From 3c7108e036c07a3c723f5eee5b75d8b89b82b25b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Cam=20Sa=C3=BCl?= <cammsaul@gmail.com> Date: Wed, 24 Aug 2016 13:27:50 -0700 Subject: [PATCH] Oracle driver :car: --- .gitignore | 1 + README.md | 1 + circle.yml | 6 +- src/metabase/core.clj | 5 + src/metabase/db/spec.clj | 10 + src/metabase/driver/oracle.clj | 229 ++++++++++++++++++ src/metabase/plugins.clj | 38 +++ src/metabase/query_processor/resolve.clj | 3 +- .../query_processor/sql_parameters.clj | 24 +- test/metabase/driver/generic_sql_test.clj | 5 +- test/metabase/query_processor_test.clj | 10 +- test/metabase/test/data.clj | 1 + test/metabase/test/data/datasets.clj | 6 +- test/metabase/test/data/interface.clj | 15 +- test/metabase/test/data/oracle.clj | 114 +++++++++ 15 files changed, 452 insertions(+), 16 deletions(-) create mode 100644 src/metabase/driver/oracle.clj create mode 100644 src/metabase/plugins.clj create mode 100644 test/metabase/test/data/oracle.clj diff --git a/.gitignore b/.gitignore index 13f3b3cebe1..5a460798f5e 100644 --- a/.gitignore +++ b/.gitignore @@ -40,3 +40,4 @@ bin/release/aws-eb/metabase-aws-eb.zip /reset-password-artifacts /.env /npm-debug.log +/plugins diff --git a/README.md b/README.md index 8fc09702b2b..59c0c8aaf26 100644 --- a/README.md +++ b/README.md @@ -35,6 +35,7 @@ For more information check out [metabase.com](http://www.metabase.com) - SQLite - H2 - Crate +- Oracle Don't see your favorite database? File an issue to let us know. diff --git a/circle.yml b/circle.yml index ae90f454c20..12c93cc19f0 100644 --- a/circle.yml +++ b/circle.yml @@ -24,6 +24,8 @@ dependencies: - pip install awscli==1.7.3 - npm cache clean - npm install -g npm@2.15.9 + - mkdir plugins + - wget --output-document=plugins/ojdbc7.jar $ORACLE_JDBC_JAR database: post: # MySQL doesn't load named timezone information automatically, you have to run this command to load it @@ -31,13 +33,13 @@ database: test: override: # 0) runs unit tests w/ H2 local DB. Runs against H2, Mongo, MySQL, BigQuery - # 1) runs unit tests w/ Postgres local DB. Runs against H2, SQL Server + # 1) runs unit tests w/ Postgres local DB. Runs against H2, SQL Server, Oracle # 2) runs unit tests w/ MySQL local DB. Runs against H2, Postgres, SQLite, Crate # 3) runs unit tests w/ H2 local DB. Runs against H2, Redshift, Druid # 4) runs Eastwood linter, Bikeshed linter, docstring-checker & ./bin/reflection-linter # 5) runs JS linter + JS test # 6) runs lein uberjar. (We don't run bin/build because we're not really concerned about `npm install` (etc) in this test, which runs elsewhere) - - case $CIRCLE_NODE_INDEX in 0) ENGINES=h2,mongo,mysql,bigquery lein test ;; 1) ENGINES=h2,sqlserver MB_DB_TYPE=postgres MB_DB_DBNAME=circle_test MB_DB_PORT=5432 MB_DB_USER=ubuntu MB_DB_HOST=localhost lein test ;; 2) ENGINES=h2,postgres,sqlite,crate MB_DB_TYPE=mysql MB_DB_DBNAME=circle_test MB_DB_PORT=3306 MB_DB_USER=ubuntu MB_DB_HOST=localhost lein test ;; 3) ENGINES=h2,redshift,druid lein test ;; 4) lein eastwood && lein bikeshed && lein docstring-checker && ./bin/reflection-linter ;; 5) npm install && npm run lint && npm run test ;; 6) lein uberjar ;; esac: + - case $CIRCLE_NODE_INDEX in 0) ENGINES=h2,mongo,mysql,bigquery lein test ;; 1) ENGINES=h2,sqlserver,oracle MB_DB_TYPE=postgres MB_DB_DBNAME=circle_test MB_DB_PORT=5432 MB_DB_USER=ubuntu MB_DB_HOST=localhost lein test ;; 2) ENGINES=h2,postgres,sqlite,crate MB_DB_TYPE=mysql MB_DB_DBNAME=circle_test MB_DB_PORT=3306 MB_DB_USER=ubuntu MB_DB_HOST=localhost lein test ;; 3) ENGINES=h2,redshift,druid lein test ;; 4) lein eastwood && lein bikeshed && lein docstring-checker && ./bin/reflection-linter ;; 5) npm install && npm run lint && npm run test ;; 6) lein uberjar ;; esac: parallel: true deployment: master: diff --git a/src/metabase/core.clj b/src/metabase/core.clj index 8257c1ccd0b..6f4217f1c63 100644 --- a/src/metabase/core.clj +++ b/src/metabase/core.clj @@ -18,6 +18,7 @@ [logger :as logger] [metabot :as metabot] [middleware :as mb-middleware] + [plugins :as plugins] [routes :as routes] [sample-data :as sample-data] [setup :as setup] @@ -96,6 +97,10 @@ ;; First of all, lets register a shutdown hook that will tidy things up for us on app exit (.addShutdownHook (Runtime/getRuntime) (Thread. ^Runnable destroy!)) + (reset! metabase-initialization-progress 0.2) + + ;; load any plugins as needed + (plugins/load-plugins!) (reset! metabase-initialization-progress 0.3) ;; Load up all of our Database drivers, which are used for app db work diff --git a/src/metabase/db/spec.clj b/src/metabase/db/spec.clj index 99c9287b043..21e04e422cd 100644 --- a/src/metabase/db/spec.clj +++ b/src/metabase/db/spec.clj @@ -66,3 +66,13 @@ :subname db :make-pool? make-pool?} (dissoc opts :db))) + +(defn oracle + "Create a database specification for an Oracle database. Opts should include keys + for :user and :password. You can also optionally set host and port." + [{:keys [host port] + :or {host "localhost", port 1521} + :as opts}] + (merge {:subprotocol "oracle:thin" + :subname (str "@" host ":" port)} + (dissoc opts :host :port))) diff --git a/src/metabase/driver/oracle.clj b/src/metabase/driver/oracle.clj new file mode 100644 index 00000000000..ffd7e7f9b4b --- /dev/null +++ b/src/metabase/driver/oracle.clj @@ -0,0 +1,229 @@ +(ns metabase.driver.oracle + (:require [clojure.java.jdbc :as jdbc] + (clojure [set :as set] + [string :as s]) + [clojure.tools.logging :as log] + [honeysql.core :as hsql] + [metabase.config :as config] + [metabase.db :as db] + [metabase.db.spec :as dbspec] + [metabase.driver :as driver] + [metabase.driver.generic-sql :as sql] + [metabase.util :as u] + [metabase.util.honeysql-extensions :as hx])) + +(def ^:private ^:const pattern->type + [;; Any types -- see http://docs.oracle.com/cd/B28359_01/server.111/b28286/sql_elements001.htm#i107578 + [#"ANYDATA" :UnknownField] ; Instance of a given type with data plus a description of the type (?) + [#"ANYTYPE" :UnknownField] ; Can be any named SQL type or an unnamed transient type + [#"ARRAY" :UnknownField] + [#"BFILE" :UnknownField] + [#"BLOB" :UnknownField] + [#"RAW" :UnknownField] + [#"CHAR" :TextField] + [#"CLOB" :TextField] + [#"DATE" :DateField] + [#"DOUBLE" :FloatField] + [#"^EXPRESSION" :UnknownField] ; Expression filter type + [#"FLOAT" :FloatField] + [#"INTERVAL" :DateTimeField] ; Does this make sense? + [#"LONG RAW" :UnknownField] + [#"LONG" :TextField] + [#"^ORD" :UnknownField] ; Media types -- http://docs.oracle.com/cd/B28359_01/server.111/b28286/sql_elements001.htm#i121058 + [#"NUMBER" :DecimalField] + [#"REAL" :FloatField] + [#"REF" :UnknownField] + [#"ROWID" :UnknownField] + [#"^SDO_" :UnknownField] ; Spatial types -- see http://docs.oracle.com/cd/B28359_01/server.111/b28286/sql_elements001.htm#i107588 + [#"STRUCT" :UnknownField] + [#"TIMESTAMP" :DateTimeField] + [#"URI" :TextField] + [#"XML" :UnknownField]]) + +(defn- connection-details->spec [{:keys [sid], :as details}] + (update (dbspec/oracle details) :subname (u/rpartial str \: sid))) + +(defn- can-connect? [details] + (let [connection (connection-details->spec details)] + (= 1M (first (vals (first (jdbc/query connection ["SELECT 1 FROM dual"]))))))) + + +(defn- trunc + "Truncate a date. See also this [table of format templates](http://docs.oracle.com/cd/B28359_01/olap.111/b28126/dml_functions_2071.htm#CJAEFAIA) + + (trunc :day v) -> TRUNC(v, 'day')" + [format-template v] + (hsql/call :trunc v (hx/literal format-template))) + +(defn- date + "Apply truncation / extraction to a date field or value for Oracle." + [unit v] + (case unit + :default (hx/->date v) + :minute (trunc :mi v) + ;; you can only extract minute + hour from TIMESTAMPs, even though DATEs still have them (WTF), so cast first + :minute-of-hour (hsql/call :extract :minute (hx/->timestamp v)) + :hour (trunc :hh v) + :hour-of-day (hsql/call :extract :hour (hx/->timestamp v)) + :day (trunc :dd v) + ;; subtract number of days between today and first day of week, then add one since first day of week = 1 + :day-of-week (hx/inc (hx/- (date :day v) + (date :week v))) + :day-of-month (hsql/call :extract :day v) + :day-of-year (hx/inc (hx/- (date :day v) (trunc :year v))) + ;; [SIC] The format template for truncating to start of week is 'day' in Oracle #WTF + :week (trunc :day v) + :week-of-year (hx/inc (hx// (hx/- (trunc :iw v) ; iw = same day of the week as first day of the ISO year + (trunc :iy v)) ; iy = ISO year + 7)) + :month (trunc :month v) + :month-of-year (hsql/call :extract :month v) + :quarter (trunc :q v) + :quarter-of-year (hx// (hx/+ (date :month-of-year (date :quarter v)) + 2) + 3) + :year (hsql/call :extract :year v))) + +(def ^:private ^:const now (hsql/raw "SYSDATE")) +(def ^:private ^:const date-1970-01-01 (hsql/call :to_timestamp (hx/literal :1970-01-01) (hx/literal :YYYY-MM-DD))) + +(defn- num-to-ds-interval [unit v] (hsql/call :numtodsinterval v (hx/literal unit))) +(defn- num-to-ym-interval [unit v] (hsql/call :numtoyminterval v (hx/literal unit))) + +(defn- date-interval + "e.g. (SYSDATE + NUMTODSINTERVAL(?, 'second'))" + [unit amount] + (hx/+ now (case unit + :second (num-to-ds-interval :second amount) + :minute (num-to-ds-interval :minute amount) + :hour (num-to-ds-interval :hour amount) + :day (num-to-ds-interval :day amount) + :week (num-to-ds-interval :day (hx/* amount (hsql/raw 7))) + :month (num-to-ym-interval :month amount) + :quarter (num-to-ym-interval :month (hx/* amount (hsql/raw 3))) + :year (num-to-ym-interval :year amount)))) + + + +(defn- unix-timestamp->timestamp [field-or-value seconds-or-milliseconds] + (hx/+ date-1970-01-01 (num-to-ds-interval :second (case seconds-or-milliseconds + :seconds field-or-value + :milliseconds (hx// field-or-value (hsql/raw 1000)))))) + +(defn- apply-offset-and-limit + "Append SQL like `OFFSET 20 FETCH FIRST 10 ROWS ONLY` to the query." + [honeysql-query offset limit] + (assoc honeysql-query + :offset (hsql/raw (format "%d ROWS FETCH NEXT %d ROWS ONLY" offset limit) ))) + +(defn- apply-limit [honeysql-query {value :limit}] + ;; Shameless hack! FETCH FIRST ... ROWS ONLY needs to go on the end of the query. Korma doesn't have any built-in + ;; way to do this but we can use `k/offset` and set it to 0. + ;; OFFSET 0 FETCH FIRST <value> ROWS ONLY + (apply-offset-and-limit honeysql-query 0 value)) + +(defn- apply-page [honeysql-query {{:keys [items page]} :page}] + ;; ex.: + ;; items | page | sql + ;; ------+------+------------------------ + ;; 5 | 1 | OFFSET 0 ROWS FETCH FIRST 5 ROWS ONLY + ;; 5 | 2 | OFFSET 5 ROWS FETCH FIRST 5 ROWS ONLY + (apply-offset-and-limit honeysql-query (* (dec page) items) items)) + +;; Oracle doesn't support `TRUE`/`FALSE`; use `1`/`0`, respectively; convert these booleans to numbers. +(defn- prepare-value [{value :value}] + (cond + (true? value) 1 + (false? value) 0 + :else value)) + +(defn- string-length-fn [field-key] + (hsql/call :length field-key)) + + +(defrecord OracleDriver [] + clojure.lang.Named + (getName [_] "Oracle")) + +(u/strict-extend OracleDriver + driver/IDriver + (merge (sql/IDriverSQLDefaultsMixin) + {:can-connect? (u/drop-first-arg can-connect?) + :date-interval (u/drop-first-arg date-interval) + :details-fields (constantly [{:name "host" + :display-name "Host" + :default "localhost"} + {:name "port" + :display-name "Port" + :type :integer + :default 1521} + {:name "sid" + :display-name "Oracle System ID" + :default "ORCL"} + {:name "user" + :display-name "Database username" + :placeholder "What username do you use to login to the database?" + :required true} + {:name "password" + :display-name "Database password" + :type :password + :placeholder "*******"}])}) + + sql/ISQLDriver + (merge (sql/ISQLDriverDefaultsMixin) + {:apply-limit (u/drop-first-arg apply-limit) + :apply-page (u/drop-first-arg apply-page) + :column->base-type (sql/pattern-based-column->base-type pattern->type) + :connection-details->spec (u/drop-first-arg connection-details->spec) + :current-datetime-fn (constantly now) + :date (u/drop-first-arg date) + :excluded-schemas (fn [& _] + (set/union + #{"ANONYMOUS" + "APEX_040200" ; TODO - are there othere APEX tables we want to skip? Maybe we should make this a pattern instead? (#"^APEX_") + "APPQOSSYS" + "AUDSYS" + "CTXSYS" + "DBSNMP" + "DIP" + "GSMADMIN_INTERNAL" + "GSMCATUSER" + "GSMUSER" + "LBACSYS" + "MDSYS" + "OLAPSYS" + "ORDDATA" + "ORDSYS" + "OUTLN" + "RDSADMIN" + "SYS" + "SYSBACKUP" + "SYSDG" + "SYSKM" + "SYSTEM" + "WMSYS" + "XDB" + "XS$NULL"} + (when config/is-test? + ;; DIRTY HACK (!) This is similar hack we do for Redshift, see the explanation there + ;; we just want to ignore all the test "session schemas" that don't match the current test + (require 'metabase.test.data.oracle) + ((resolve 'metabase.test.data.oracle/non-session-schemas))))) + :field-percent-urls sql/slow-field-percent-urls + ;; TODO - we *should* be able to set timezone using the SQL below, but I think the SQL doesn't work with prepared params (i.e., '?') + ;; Find some way to work around this for Oracle + ;; :set-timezone-sql (constantly "ALTER session SET time_zone = ?") + :prepare-value (u/drop-first-arg prepare-value) + :string-length-fn (u/drop-first-arg string-length-fn) + :unix-timestamp->timestamp (u/drop-first-arg unix-timestamp->timestamp)})) + +;; only register the Oracle driver if the JDBC driver is available +(when (u/ignore-exceptions + (Class/forName "oracle.jdbc.OracleDriver")) + + ;; By default the Oracle JDBC driver isn't compliant with JDBC standards -- instead of returning types like java.sql.Timestamp + ;; it returns wacky types like oracle.sql.TIMESTAMPT. By setting this System property the JDBC driver will return the appropriate types. + ;; See this page for more details: http://docs.oracle.com/database/121/JJDBC/datacc.htm#sthref437 + (.setProperty (System/getProperties) "oracle.jdbc.J2EE13Compliant" "TRUE") + + (driver/register-driver! :oracle (OracleDriver.))) diff --git a/src/metabase/plugins.clj b/src/metabase/plugins.clj new file mode 100644 index 00000000000..190235f0ff0 --- /dev/null +++ b/src/metabase/plugins.clj @@ -0,0 +1,38 @@ +(ns metabase.plugins + (:require [clojure.java.io :as io] + [clojure.tools.logging :as log] + [metabase.config :as config] + [metabase.util :as u]) + (:import (java.net URL URLClassLoader))) + +(defn- plugins-dir + "The Metabase plugins directory. This defaults to `plugins/` in the same directory as `metabase.jar`, but can be configured via the env var `MB_PLUGINS_DIR`." + ^java.io.File [] + (let [dir (io/file (or (config/config-str :mb-plugins-dir) + (str (System/getProperty "user.dir") "/plugins")))] + (when (and (.isDirectory dir) + (.canRead dir)) + dir))) + + +(defn- add-jar-to-classpath! + "Dynamically add a JAR file to the classpath. + See also [this SO post](http://stackoverflow.com/questions/60764/how-should-i-load-jars-dynamically-at-runtime/60766#60766)" + [^java.io.File jar-file] + (let [sysloader (ClassLoader/getSystemClassLoader) + method (.getDeclaredMethod URLClassLoader "addURL" (into-array Class [URL]))] + (.setAccessible method true) + (.invoke method sysloader (into-array URL [(.toURL (.toURI jar-file))])))) + +(defn load-plugins! + "Dynamically add any JARs in the `plugins-dir` to the classpath. + This is used for things like custom plugins or the Oracle JDBC driver, which cannot be shipped alongside Metabase for licensing reasons." + [] + (when-let [^java.io.File dir (plugins-dir)] + (log/info (format "Loading plugins in directory %s..." dir)) + (doseq [^java.io.File file (.listFiles dir) + :when (and (.isFile file) + (.canRead file) + (re-find #"\.jar$" (.getPath file)))] + (log/info (u/format-color 'magenta "Loading plugin %s... 🔌" file)) + (add-jar-to-classpath! file)))) diff --git a/src/metabase/query_processor/resolve.clj b/src/metabase/query_processor/resolve.clj index 55b8e49cd05..eaa0628d5ce 100644 --- a/src/metabase/query_processor/resolve.clj +++ b/src/metabase/query_processor/resolve.clj @@ -237,7 +237,8 @@ :field-name target-field-name}) :source-field (map->JoinTableField {:field-id source-field-id :field-name source-field-name}) - :join-alias (str target-table-name "__via__" source-field-name)}))))) + ;; some DBs like Oracle limit the length of identifiers to 30 characters so only take the first 30 here + :join-alias (apply str (take 30 (str target-table-name "__via__" source-field-name)))}))))) (defn- resolve-tables "Resolve the `Tables` in an EXPANDED-QUERY-DICT." diff --git a/src/metabase/query_processor/sql_parameters.clj b/src/metabase/query_processor/sql_parameters.clj index becdf03607c..b80a38b13f6 100644 --- a/src/metabase/query_processor/sql_parameters.clj +++ b/src/metabase/query_processor/sql_parameters.clj @@ -35,12 +35,19 @@ (first (hsql/format x :quoting ((resolve 'metabase.driver.generic-sql/quote-style) *driver*)))) +(defn- format-oracle-date [s] + (format "TO_TIMESTAMP('%s', 'yyyy-MM-dd')" (u/format-date "yyyy-MM-dd" (u/->Date s)))) + +(defn- oracle-driver? ^Boolean [] + (when-let [oracle-driver-class (u/ignore-exceptions (Class/forName "metabase.driver.oracle.OracleDriver"))] + (instance? oracle-driver-class *driver*))) + (extend-protocol ISQLParamSubstituion nil (->sql [_] "NULL") Object (->sql [this] (str this)) Boolean (->sql [this] (if this "TRUE" "FALSE")) NumberValue (->sql [this] (:value this)) - String (->sql [this] (str \' (s/replace this #"'" "\\\\'") \')) + String (->sql [this] (str \' (s/replace this #"'" "\\\\'") \')) ; quote single quotes inside the string Keyword (->sql [this] (honeysql->sql this)) SqlCall (->sql [this] (honeysql->sql this)) @@ -53,9 +60,18 @@ DateRange (->sql [{:keys [start end]}] - (if (= start end) - (format "= '%s'" start) - (format "BETWEEN '%s' AND '%s'" start end))) + ;; This is a dirty dirty HACK! Unfortuantely Oracle is super-dumb when it comes to automatically converting strings to dates + ;; so we need to add the cast here + ;; TODO - fix this when we move to support native params in non-SQL databases + ;; Perhaps by making ->sql a multimethod that dispatches off of type and engine + (if (oracle-driver?) + (if (= start end) + (format "= %s" (format-oracle-date start)) + (format "BETWEEN %s AND %s" (format-oracle-date start) (format-oracle-date end))) + ;; Not the Oracle driver + (if (= start end) + (format "= '%s'" start) + (format "BETWEEN '%s' AND '%s'" start end)))) Dimension (->sql [{:keys [field param]}] diff --git a/test/metabase/driver/generic_sql_test.clj b/test/metabase/driver/generic_sql_test.clj index 81ec4a545b8..ec784d7907a 100644 --- a/test/metabase/driver/generic_sql_test.clj +++ b/test/metabase/driver/generic_sql_test.clj @@ -117,6 +117,9 @@ ;;; FIELD-PERCENT-URLS (datasets/expect-with-engines @generic-sql-engines - 0.5 + (if (= datasets/*engine* :oracle) + ;; Oracle considers empty strings to be NULL strings; thus in this particular test `percent-valid-urls` gives us 4/7 valid valid where other DBs give us 4/8 + 0.5714285714285714 + 0.5) (dataset half-valid-urls (field-percent-urls datasets/*driver* (db/select-one 'Field :id (id :urls :url))))) diff --git a/test/metabase/query_processor_test.clj b/test/metabase/query_processor_test.clj index 215a229acc4..87c855e7700 100644 --- a/test/metabase/query_processor_test.clj +++ b/test/metabase/query_processor_test.clj @@ -1402,9 +1402,9 @@ ;;; ------------------------------------------------------------ BUCKETING ------------------------------------------------------------ -(defn- ->int-if-number [x] +(defn- ->long-if-number [x] (if (number? x) - (int x) + (long x) x)) (defn- sad-toucan-incidents-with-bucketing [unit] @@ -1413,7 +1413,7 @@ (ql/aggregation (ql/count)) (ql/breakout (ql/datetime-field $timestamp unit)) (ql/limit 10))) - rows (format-rows-by [->int-if-number int]))) + rows (format-rows-by [->long-if-number int]))) (expect-with-non-timeseries-dbs (cond @@ -1429,7 +1429,7 @@ ["2015-06-02 08:20:00" 1] ["2015-06-02 11:11:00" 1]] - (contains? #{:redshift :sqlserver :bigquery :mongo :postgres :h2} *engine*) + (contains? #{:redshift :sqlserver :bigquery :mongo :postgres :h2 :oracle} *engine*) [["2015-06-01T10:31:00.000Z" 1] ["2015-06-01T16:06:00.000Z" 1] ["2015-06-01T17:23:00.000Z" 1] @@ -1635,7 +1635,7 @@ (expect-with-non-timeseries-dbs ;; Not really sure why different drivers have different opinions on these </3 (cond - (contains? #{:sqlserver :sqlite :crate} *engine*) + (contains? #{:sqlserver :sqlite :crate :oracle} *engine*) [[23 54] [24 46] [25 39] [26 61]] (contains? #{:mongo :redshift :bigquery :postgres :h2} *engine*) diff --git a/test/metabase/test/data.clj b/test/metabase/test/data.clj index 40feecafdd1..bb944bc9b89 100644 --- a/test/metabase/test/data.clj +++ b/test/metabase/test/data.clj @@ -122,6 +122,7 @@ {:pre [(integer? db-id) (u/string-or-keyword? table-name)]} (let [table-name (format-name table-name)] (or (db/select-one-id Table, :db_id db-id, :name table-name) + (db/select-one-id Table, :db_id db-id, :name (i/db-qualified-table-name (db/select-one-field :name Database :id db-id) table-name)) (throw (Exception. (format "No Table '%s' found for Database %d.\nFound: %s" table-name db-id (u/pprint-to-str (db/select-id->field :name Table, :db_id db-id, :active true)))))))) diff --git a/test/metabase/test/data/datasets.clj b/test/metabase/test/data/datasets.clj index 5e9826bc5bc..6205d92aeb5 100644 --- a/test/metabase/test/data/datasets.clj +++ b/test/metabase/test/data/datasets.clj @@ -6,9 +6,13 @@ [environ.core :refer [env]] [expectations :refer [expect]] (metabase [config :as config] - [driver :as driver]) + [driver :as driver] + [plugins :as plugins]) [metabase.test.data.interface :as i])) +;; When running tests, we need to make sure plugins (i.e., the Oracle JDBC driver) are loaded because otherwise the Oracle driver won't show up in the list of valid drivers below +(plugins/load-plugins!) + (driver/find-and-load-drivers!) (def ^:const all-valid-engines (set (keys (driver/available-drivers)))) diff --git a/test/metabase/test/data/interface.clj b/test/metabase/test/data/interface.clj index a438f1276ee..996af1c691a 100644 --- a/test/metabase/test/data/interface.clj +++ b/test/metabase/test/data/interface.clj @@ -34,11 +34,20 @@ ^String [^DatabaseDefinition database-definition] (s/replace (:database-name database-definition) #"\s+" "_")) +(defn db-qualified-table-name + "Return a combined table name qualified with the name of its database, suitable for use as an identifier. + Provided for drivers where testing wackiness makes it hard to actually create separate Databases, such as Oracle, where this is disallowed on RDS. + (Since Oracle can't create seperate DBs, we just create various tables in the same DB; thus their names must be qualified to differentiate them effectively.)" + ^String [^String database-name, ^String table-name] + {:pre [(string? database-name) (string? table-name)]} + ;; take up to last 30 characters because databases like Oracle have limits on the lengths of identifiers + (apply str (take-last 30 (s/replace (s/lower-case (str database-name \_ table-name)) #"-" "_")))) + (defprotocol IMetabaseInstance (metabase-instance [this context] "Return the Metabase object associated with this definition, if applicable. CONTEXT should be the parent - object of the Metabase object to return (e.g., a pass a `Table` to a `FieldDefintion`). For a `DatabaseDefinition`, + object (the actual instance, *not* the definition) of the Metabase object to return (e.g., a pass a `Table` to a `FieldDefintion`). For a `DatabaseDefinition`, pass the engine keyword.")) (extend-protocol IMetabaseInstance @@ -48,7 +57,9 @@ TableDefinition (metabase-instance [this database] - (Table :db_id (:id database), :%lower.name (s/lower-case (:table-name this)))) + ;; Look first for an exact table-name match; otherwise allow DB-qualified table names for drivers that need them like Oracle + (or (Table :db_id (:id database), :%lower.name (s/lower-case (:table-name this))) + (Table :db_id (:id database), :%lower.name (db-qualified-table-name (:name database) (:table-name this))))) DatabaseDefinition (metabase-instance [{:keys [database-name]} engine-kw] diff --git a/test/metabase/test/data/oracle.clj b/test/metabase/test/data/oracle.clj new file mode 100644 index 00000000000..17623046148 --- /dev/null +++ b/test/metabase/test/data/oracle.clj @@ -0,0 +1,114 @@ +(ns metabase.test.data.oracle + (:require [clojure.java.jdbc :as jdbc] + [clojure.string :as s] + [environ.core :refer [env]] + [metabase.driver.generic-sql :as sql] + [metabase.test.data :as data] + (metabase.test.data [datasets :as datasets] + [generic-sql :as generic] + [interface :as i]) + [metabase.util :as u]) + (:import metabase.driver.oracle.OracleDriver)) + +(defn- get-db-env-var + " Look up the relevant connection param from corresponding env var or throw an exception if it's not set. + + (get-db-env-var :user) ; Look up `MB_ORACLE_USER`" + [env-var & [default]] + (or (env (keyword (format "mb-oracle-%s" (name env-var)))) + default + (throw (Exception. (format "In order to test Oracle, you must specify the env var MB_ORACLE_%s." + (s/upper-case (name env-var))))))) + +;; Similar to SQL Server, Oracle on AWS doesn't let you create different databases; like Redshift, we'll create a series of schemas for each DB, with a unique prefix for this "session" +(defonce ^:private ^:const session-schema-number (rand-int 200)) +(defonce ^:private ^:const session-schema (str "CAM_" session-schema-number)) +(defonce ^:private ^:const session-password (apply str (repeatedly 16 #(rand-nth (map char (range (int \a) (inc (int \z)))))))) + + +(def ^:private db-connection-details + (delay {:host (get-db-env-var :host) + :port (Integer/parseInt (get-db-env-var :port "1521")) + :user (get-db-env-var :user) + :password (get-db-env-var :password) + :sid (get-db-env-var :sid) + :short-lived? false})) + + +(def ^:private ^:const field-base-type->sql-type + {:BigIntegerField "NUMBER(*,0)" + :BooleanField "NUMBER(1)" + :CharField "VARCHAR2(254)" + :DateField "DATE" + :DateTimeField "TIMESTAMP" #_"TIMESTAMP WITH TIME ZONE" + :DecimalField "DECIMAL" + :FloatField "BINARY_FLOAT" + :IntegerField "INTEGER" + :TextField "VARCHAR2(4000)"}) ; Oracle doesn't have a TEXT type so use the maximum size for a VARCHAR2 + +(defn- drop-table-if-exists-sql [{:keys [database-name]} {:keys [table-name]}] + (format "BEGIN + EXECUTE IMMEDIATE 'DROP TABLE \"%s\".\"%s\" CASCADE CONSTRAINTS'⅋ + EXCEPTION + WHEN OTHERS THEN + IF SQLCODE != -942 THEN + RAISE⅋ + END IF⅋ + END⅋" + session-schema + (i/db-qualified-table-name database-name table-name))) + +(defn- qualified-name-components + ([db-name] [db-name]) + ([db-name table-name] [session-schema (i/db-qualified-table-name db-name table-name)]) + ([db-name table-name field-name] [session-schema (i/db-qualified-table-name db-name table-name) field-name])) + +(extend OracleDriver + generic/IGenericSQLDatasetLoader + (merge generic/DefaultsMixin + {:create-db-sql (constantly nil) + :drop-db-if-exists-sql (constantly nil) + :drop-table-if-exists-sql (u/drop-first-arg drop-table-if-exists-sql) + :execute-sql! generic/sequentially-execute-sql! + :field-base-type->sql-type (u/drop-first-arg field-base-type->sql-type) + :load-data! generic/load-data-one-at-a-time-parallel! + :pk-sql-type (constantly "INTEGER GENERATED BY DEFAULT AS IDENTITY (START WITH 1 INCREMENT BY 1) NOT NULL") ; LOL + :qualified-name-components (u/drop-first-arg qualified-name-components)}) + + i/IDatasetLoader + (merge generic/IDatasetLoaderMixin + {:database->connection-details (fn [& _] @db-connection-details) + :default-schema (constantly session-schema) + :engine (constantly :oracle) + :expected-base-type->actual (fn [_ base-type] + (condp = base-type + :IntegerField :DecimalField ; Oracle doesn't have INTEGERs + :BigIntegerField :DecimalField + base-type)) + :id-field-type (constantly :DecimalField)})) + +(defn- dbspec [] + (sql/connection-details->spec (OracleDriver.) @db-connection-details)) + +(defn- non-session-schemas + "Return a set of the names of schemas (users) that are not meant for use in this test session (i.e., ones that should be ignored)." + [] + (set (map :username (jdbc/query (dbspec) ["SELECT username FROM dba_users WHERE username <> ?" session-schema])))) + + +;;; Clear out the sesion schema before and after tests run +;; TL;DR Oracle schema == Oracle user. Create new user for session-schema +(def ^:private execute-when-testing-oracle! + (partial generic/execute-when-testing! :oracle (fn [& _] (dbspec)))) + +(defn- create-session-user! + {:expectations-options :before-run} + [] + (u/ignore-exceptions + (execute-when-testing-oracle! (format "DROP USER %s CASCADE" session-schema))) + (execute-when-testing-oracle! (format "CREATE USER %s IDENTIFIED BY %s DEFAULT TABLESPACE USERS QUOTA UNLIMITED ON USERS" session-schema session-password))) + +(defn- destroy-session-user! + {:expectations-options :after-run} + [] + (execute-when-testing-oracle! (format "DROP USER %s CASCADE" session-schema))) -- GitLab