diff --git a/CHANGELOG.md b/CHANGELOG.md index ada4669..15e345d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -2,9 +2,14 @@ Only accretive/fixative changes will be made from now on. -Changes made on master since 1.0.476: * WIP: nested transaction support! +Changes made since the 1.0.478 release: +* Address #125 by making the result of `plan` foldable (in the `clojure.core.reducers` sense). +* Address #124 by extending `next.jdbc.sql.builder/for-query` to support `:top` (SQL Server), `:limit` / `:offset` (MySQL/PostgreSQL), `:offset` / `:fetch` (SQL Standard). +* Allow `:all` to be passed into `find-by-keys` instead of an example hash map or a where clause vector so all rows will be returned (expected to be used with `:offset` etc to support simple pagination of an entire table). +* Add `:columns` option to `find-by-keys` (and `get-by-id`) to specify a subset of columns to be returned in each row. This can also specify an alias for the column and allows for computed expressions to be selected with an alias. + ## Stable Builds * 2020-06-24 -- 1.0.478 diff --git a/doc/all-the-options.md b/doc/all-the-options.md index 43fad29..e9608fe 100644 --- a/doc/all-the-options.md +++ b/doc/all-the-options.md @@ -34,11 +34,23 @@ If you need additional options set on a connection, you can either use Java inte ## Generating SQL -The "friendly" SQL functions all accept the following options (in addition to all the options that `plan`, `execute!`, and `execute-one!` can accept): +Except for `query` (which is simply an alias for `execute!`), all the "friendly" SQL functions accept the following options (in addition to all the options that `plan`, `execute!`, and `execute-one!` can accept): * `:table-fn` -- the quoting function to be used on the string that identifies the table name, if provided, * `:column-fn` -- the quoting function to be used on any string that identifies a column name, if provided. +They also support a `:suffix` argument which can be used to specify a SQL string that should be appended to the generated SQL string before executing it, e.g., `:suffix "FOR UPDATE"`. + +In addition, `find-by-keys` accepts the following options (see its docstring for more details): + +* `:columns` -- specify one or more columns to `SELECT` to override selecting all columns, +* `:order-by` -- specify one or more columns, on which to sort the results, +* `:top` / `:limit` / `:offset` / `:fetch` to support pagination of results. + +In the simple case, the `:columns` option expects a vector of keywords and each will be processed according to `:column-fn`, if provided. A column alias can be specified using a vector pair of keywords and both will be processed according to `:column-fn`, e.g., `[:foo [:bar :quux]]` would expand to `foo, bar AS quux`. You can also specify the first element of the pair as a string which will be used as-is in the generated SQL, e.g., `[:foo ["COUNT(*)" :total]]` would expand to `foo, COUNT(*) AS total`. In the latter case, the alias keyword will still be processed according to `:column-fn` but the string will be untouched -- you are responsible for any quoting and/or other formatting that might be required to produce a valid SQL expression. + +> Note: `get-by-id` accepts the same options as `find-by-keys` but it will only ever produce one row, as a hash map, so sort order and pagination are less applicable, although `:columns` may be useful. + ## Generating Rows and Result Sets Any function that might realize a row or a result set will accept: diff --git a/doc/friendly-sql-functions.md b/doc/friendly-sql-functions.md index a27be3e..565a079 100644 --- a/doc/friendly-sql-functions.md +++ b/doc/friendly-sql-functions.md @@ -113,6 +113,26 @@ Given a table name (as a keyword) and either a hash map of column names and valu "Stella" "stella@artois.beer"]) ``` +The default behavior is to return all the columns in each row. You can specify a subset of columns to return using the `:columns` option. It takes a vector and each element of the vector can be: + +* a simple keyword representing the column name (`:column-fn` will be applied, if provided), +* a pair of keywords representing the column name and an alias (`:column-fn` will be applied to both, if provided), +* a pair consisting of a string and a keyword, representing a SQL expression and an alias (`:column-fn` will be applied to the alias, if provided). + +```clojure +(sql/find-by-keys ds :address {:name "Stella"} {:columns [[:email :address]]}) +;; equivalent to +(jdbc/execute! ds ["SELECT email AS address FROM address WHERE name = ?" + "Stella"]) + +(sql/find-by-keys ds :address {:name "Stella"} {:columns [["count(*)" :n]]}) +;; equivalent to +(jdbc/execute! ds ["SELECT count(*) AS n FROM address WHERE name = ?" + "Stella"]) +``` + +> Note: the SQL string provided for a column is copied exactly as-is into the generated SQL -- you are responsible for ensuring it is legal SQL! + `find-by-keys` supports an `:order-by` option which can specify a vector of column names to sort the results by. Elements may be column names or pairs of a column name and the direction to sort: `:asc` or `:desc`: ```clojure @@ -124,6 +144,16 @@ Given a table name (as a keyword) and either a hash map of column names and valu "Stella" "stella@artois.beer"]) ``` +`find-by-keys` also supports basic pagination with `:offset` and `:fetch` options which both accept numeric values and adds `OFFSET ? ROWS FETCH NEXT ? ROWS ONLY` to the generated query. To support MySQL and SQLite, you can specify `:limit` instead `:fetch` which adds `LIMIT ? OFFSET ?` to the generated query instead. + +If you want to match all rows in a table -- perhaps with the pagination options in effect -- you can pass the keyword `:all` instead of either a hash map of column names and values or a vector containing a partial `WHERE` clause and parameters. + +```clojure +(sql/find-by-keys ds :address :all {:order-by [:id] :offset 5 :fetch 10}) +;; equivalent to +(jdbc/execute! ds ["SELECT * FROM address ORDER BY id OFFSET ? ROWS FETCH NEXT ? ROWS ONLY" 5 10]) +``` + If no rows match, `find-by-keys` returns `[]`, just like `execute!`. ## `get-by-id` diff --git a/doc/tips-and-tricks.md b/doc/tips-and-tricks.md index 70635b4..968e20d 100644 --- a/doc/tips-and-tricks.md +++ b/doc/tips-and-tricks.md @@ -2,6 +2,16 @@ This page contains various tips and tricks that make it easier to use `next.jdbc` with a variety of databases. It is mostly organized by database, but there are a few that are cross-database and those are listed first. +## Reducing and Folding with `plan` + +Most of this documentation describes using `plan` specifically for reducing and notes that you can avoid the overhead of realizing rows from the `ResultSet` into Clojure data structures if your reducing function uses only functions that get column values by name. If you perform any function on the row that would require an actual hash map or a sequence, the row will be realized into a full Clojure hash map via the builder function passed in the options (or via `next.jdbc.result-set/as-maps` by default). + +One of the benefits of reducing over `plan` is that you can stream very large result sets, very efficiently, without having the entire result set in memory (assuming your reducing function doesn't build a data structure that is too large!). See the tips below on **Streaming Result Sets**. + +The result of `plan` is also foldable in the [clojure.core.reducers](https://clojure.org/reference/reducers) sense. While you could use `execute!` to produce a vector of fully-realized rows as hash maps and then fold that vector (Clojure's vectors support fork-join parallel reduce-combine), that wouldn't be possible for very large result sets. If you fold the result of `plan`, the result set will be partitioned and processed using fork-join parallel reduce-combine. Unlike reducing over `plan`, each row **is** realized into a Clojure data structure and each batch is forked for reduction as soon as that many rows have been realized. By default, `fold`'s batch size is 512 but you can specify a different value in the 4-arity call. Once the entire result set has been read, the last (partial) batch is forked for reduction and then all of the reduced batches are combined. + +There is no back pressure here so if your reducing function is slow, you may end up with more of the realized result set in memory than your system can cope with. + ## CLOB & BLOB SQL Types Columns declared with the `CLOB` or `BLOB` SQL types are typically rendered into Clojure result sets as database-specific custom types but they should implement `java.sql.Clob` or `java.sql.Blob` (as appropriate). In general, you can only read the data out of those Java objects during the current transaction, which effectively means that you need to do it either inside the reduction (for `plan`) or inside the result set builder (for `execute!` or `execute-one!`). If you always treat these types the same way for all columns across the whole of your application, you could simply extend `next.jdbc.result-set/ReadableColumn` to `java.sql.Clob` (and/or `java.sql.Blob`). Here's an example for reading `CLOB` into a `String`: diff --git a/src/next/jdbc.clj b/src/next/jdbc.clj index f9b9f08..b46283f 100644 --- a/src/next/jdbc.clj +++ b/src/next/jdbc.clj @@ -176,6 +176,9 @@ "General SQL execution function (for working with result sets). Returns a reducible that, when reduced, runs the SQL and yields the result. + The reducible is also foldable (in the `clojure.core.reducers` sense) but + see the **Tips & Tricks** section of the documentation for some important + caveats about that. Can be called on a `PreparedStatement`, a `Connection`, or something that can produce a `Connection` via a `DataSource`. diff --git a/src/next/jdbc/result_set.clj b/src/next/jdbc/result_set.clj index c2aef20..98dd9da 100644 --- a/src/next/jdbc/result_set.clj +++ b/src/next/jdbc/result_set.clj @@ -18,6 +18,7 @@ for implementations of `ReadableColumn` that provide automatic conversion of some SQL data types to Java Time objects." (:require [clojure.core.protocols :as core-p] + [clojure.core.reducers :as r] [clojure.datafy :as d] [next.jdbc.prepare :as prepare] [next.jdbc.protocols :as p]) @@ -26,7 +27,8 @@ ResultSet ResultSetMetaData Statement SQLException) - (java.util Locale))) + (java.util Locale) + (java.util.concurrent ForkJoinPool ForkJoinTask))) (set! *warn-on-reflection* true) @@ -602,17 +604,69 @@ init'))) (f init {:next.jdbc/update-count (.getUpdateCount stmt)}))) +;; ForkJoinTask wrappers copied in from clojure.core.reducers to avoid +;; relying on private functionality that might possibly change over time + +(defn- fjtask [^Callable f] + (ForkJoinTask/adapt f)) + +(defn- fjinvoke + "For now, this still relies on clojure.core.reducers/pool which is + public but undocumented." + [f] + (if (ForkJoinTask/inForkJoinPool) + (f) + (.invoke ^ForkJoinPool @r/pool ^ForkJoinTask (fjtask f)))) + +(defn- fjfork [task] (.fork ^ForkJoinTask task)) + +(defn- fjjoin [task] (.join ^ForkJoinTask task)) + +(defn- fold-stmt + "Execute the `PreparedStatement`, attempt to get either its `ResultSet` or + its generated keys (as a `ResultSet`), and fold that using the supplied + batch size, combining function, and reducing function. + + If the statement yields neither a `ResultSet` nor generated keys, produce + a hash map containing `:next.jdbc/update-count` and the number of rows + updated, and fold that as a single element collection." + [^PreparedStatement stmt n combinef reducef connectable opts] + (if-let [rs (stmt->result-set stmt opts)] + (let [rs-map (mapify-result-set rs opts) + chunk (fn [batch] (fjtask #(r/reduce reducef (combinef) batch))) + realize (fn [row] (datafiable-row row connectable opts))] + (loop [batch [] task nil] + (if (.next rs) + (if (= n (count batch)) + (recur [(realize rs-map)] + (let [t (fjfork (chunk batch))] + (if task + (fjfork + (fjtask #(combinef (fjjoin task) + (fjjoin t)))) + t))) + (recur (conj batch (realize rs-map)) task)) + (if (seq batch) + (let [t (fjfork (chunk batch))] + (fjinvoke + #(combinef (if task (fjjoin task) (combinef)) + (fjjoin t)))) + (if task + (fjinvoke + #(combinef (combinef) (fjjoin task))) + (combinef)))))) + (reducef (combinef) {:next.jdbc/update-count (.getUpdateCount stmt)}))) + (defn- stmt-sql->result-set "Given a `Statement`, a SQL command, and options, execute it and return a `ResultSet` if possible." ^ResultSet - [^Statement stmt ^String sql opts] + [^Statement stmt ^String sql] (if (.execute stmt sql) (.getResultSet stmt) - (when (:return-keys opts) - (try - (.getGeneratedKeys stmt) - (catch Exception _))))) + (try + (.getGeneratedKeys stmt) + (catch Exception _)))) (defn- reduce-stmt-sql "Execute the SQL command on the given `Statement`, attempt to get either @@ -623,7 +677,7 @@ a hash map containing `:next.jdbc/update-count` and the number of rows updated, with the supplied function and initial value applied." [^Statement stmt sql f init opts] - (if-let [rs (stmt-sql->result-set stmt sql opts)] + (if-let [rs (stmt-sql->result-set stmt sql)] (let [rs-map (mapify-result-set rs opts)] (loop [init' init] (if (.next rs) @@ -634,16 +688,59 @@ init'))) (f init {:next.jdbc/update-count (.getUpdateCount stmt)}))) +(defn- fold-stmt-sql + "Execute the SQL command on the given `Statement`, attempt to get either + its `ResultSet` or its generated keys (as a `ResultSet`), and fold that + using the supplied batch size, combining function, and reducing function. + + If the statement yields neither a `ResultSet` nor generated keys, produce + a hash map containing `:next.jdbc/update-count` and the number of rows + updated, and fold that as a single element collection." + [^Statement stmt sql n combinef reducef connectable opts] + (if-let [rs (stmt-sql->result-set stmt sql)] + (let [rs-map (mapify-result-set rs opts) + chunk (fn [batch] (fjtask #(r/reduce reducef (combinef) batch))) + realize (fn [row] (datafiable-row row connectable opts))] + (loop [batch [] task nil] + (if (.next rs) + (if (= n (count batch)) + (recur [(realize rs-map)] + (let [t (fjfork (chunk batch))] + (if task + (fjfork + (fjtask #(combinef (fjjoin task) + (fjjoin t)))) + t))) + (recur (conj batch (realize rs-map)) task)) + (if (seq batch) + (let [t (fjfork (chunk batch))] + (fjinvoke + #(combinef (if task (fjjoin task) (combinef)) + (fjjoin t)))) + (if task + (fjinvoke + #(combinef (combinef) (fjjoin task))) + (combinef)))))) + (reducef (combinef) {:next.jdbc/update-count (.getUpdateCount stmt)}))) + (extend-protocol p/Executable java.sql.Connection (-execute [this sql-params opts] - (reify clojure.lang.IReduceInit + (reify + clojure.lang.IReduceInit (reduce [_ f init] - (with-open [stmt (prepare/create this - (first sql-params) - (rest sql-params) - opts)] - (reduce-stmt stmt f init opts))) + (with-open [stmt (prepare/create this + (first sql-params) + (rest sql-params) + opts)] + (reduce-stmt stmt f init opts))) + r/CollFold + (coll-fold [_ n combinef reducef] + (with-open [stmt (prepare/create this + (first sql-params) + (rest sql-params) + opts)] + (fold-stmt stmt n combinef reducef this opts))) (toString [_] "`IReduceInit` from `plan` -- missing reduction?"))) (-execute-one [this sql-params opts] (with-open [stmt (prepare/create this @@ -667,14 +764,23 @@ javax.sql.DataSource (-execute [this sql-params opts] - (reify clojure.lang.IReduceInit + (reify + clojure.lang.IReduceInit (reduce [_ f init] - (with-open [con (p/get-connection this opts) - stmt (prepare/create con - (first sql-params) - (rest sql-params) - opts)] - (reduce-stmt stmt f init opts))) + (with-open [con (p/get-connection this opts) + stmt (prepare/create con + (first sql-params) + (rest sql-params) + opts)] + (reduce-stmt stmt f init opts))) + r/CollFold + (coll-fold [_ n combinef reducef] + (with-open [con (p/get-connection this opts) + stmt (prepare/create con + (first sql-params) + (rest sql-params) + opts)] + (fold-stmt stmt n combinef reducef this opts))) (toString [_] "`IReduceInit` from `plan` -- missing reduction?"))) (-execute-one [this sql-params opts] (with-open [con (p/get-connection this opts) @@ -703,9 +809,14 @@ ;; keys so we pass a truthy value to at least attempt it if we ;; do not get a ResultSet back from the execute call (-execute [this _ opts] - (reify clojure.lang.IReduceInit + (reify + clojure.lang.IReduceInit (reduce [_ f init] - (reduce-stmt this f init (assoc opts :return-keys true))) + (reduce-stmt this f init (assoc opts :return-keys true))) + r/CollFold + (coll-fold [_ n combinef reducef] + (fold-stmt this n combinef reducef (.getConnection this) + (assoc opts :return-keys true))) (toString [_] "`IReduceInit` from `plan` -- missing reduction?"))) (-execute-one [this _ opts] (if-let [rs (stmt->result-set this (assoc opts :return-keys true))] @@ -721,20 +832,22 @@ [{:next.jdbc/update-count (.getUpdateCount this)}])) java.sql.Statement - ;; we can't tell if this Statement will return generated - ;; keys so we pass a truthy value to at least attempt it if we - ;; do not get a ResultSet back from the execute call (-execute [this sql-params opts] (assert (= 1 (count sql-params)) "Parameters cannot be provided when executing a non-prepared Statement") - (reify clojure.lang.IReduceInit + (reify + clojure.lang.IReduceInit (reduce [_ f init] - (reduce-stmt-sql this (first sql-params) f init (assoc opts :return-keys true))) + (reduce-stmt-sql this (first sql-params) f init opts)) + r/CollFold + (coll-fold [_ n combinef reducef] + (fold-stmt-sql this (first sql-params) n combinef reducef + (.getConnection this) opts)) (toString [_] "`IReduceInit` from `plan` -- missing reduction?"))) (-execute-one [this sql-params opts] (assert (= 1 (count sql-params)) "Parameters cannot be provided when executing a non-prepared Statement") - (if-let [rs (stmt-sql->result-set this (first sql-params) (assoc opts :return-keys true))] + (if-let [rs (stmt-sql->result-set this (first sql-params))] (let [builder-fn (get opts :builder-fn as-maps) builder (builder-fn rs opts)] (when (.next rs) @@ -744,7 +857,7 @@ (-execute-all [this sql-params opts] (assert (= 1 (count sql-params)) "Parameters cannot be provided when executing a non-prepared Statement") - (if-let [rs (stmt-sql->result-set this (first sql-params) opts)] + (if-let [rs (stmt-sql->result-set this (first sql-params))] (datafiable-result-set rs (.getConnection this) opts) [{:next.jdbc/update-count (.getUpdateCount this)}])) diff --git a/src/next/jdbc/specs.clj b/src/next/jdbc/specs.clj index bb4274d..6d63ea2 100644 --- a/src/next/jdbc/specs.clj +++ b/src/next/jdbc/specs.clj @@ -70,12 +70,22 @@ (s/def ::key-map (s/map-of keyword? any?)) (s/def ::example-map (s/map-of keyword? any? :min-count 1)) +;; can be a simple column name (keyword) or a pair of something and as alias +;; and that something can be a simple column name (keyword) or an arbitrary +;; expression (string) where we assume you know what you're doing +(s/def ::column-spec (s/or :column keyword? + :alias (s/and vector? + (s/cat :expr (s/or :col keyword? + :str string?) + :column keyword?)))) +(s/def ::columns (s/coll-of ::column-spec :kind vector?)) + (s/def ::order-by-col (s/or :col keyword? :dir (s/cat :col keyword? :dir #{:asc :desc}))) (s/def ::order-by (s/coll-of ::order-by-col :kind vector? :min-count 1)) (s/def ::opts-map (s/and (s/map-of keyword? any?) - (s/keys :opt-un [::order-by]))) + (s/keys :opt-un [::columns ::order-by]))) (s/def ::transactable any?) @@ -138,6 +148,10 @@ :args (s/cat :clazz #(instance? Class %) :db-spec ::db-spec-or-jdbc)) +(s/fdef connection/component + :args (s/cat :clazz #(instance? Class %) + :db-spec ::db-spec-or-jdbc)) + (s/fdef prepare/execute-batch! :args (s/cat :ps ::prepared-statement :param-groups (s/coll-of ::params :kind sequential?) @@ -174,7 +188,8 @@ :args (s/cat :connectable ::connectable :table keyword? :key-map (s/or :example ::example-map - :where ::sql-params) + :where ::sql-params + :all #{:all}) :opts (s/? ::opts-map))) (s/fdef sql/get-by-id diff --git a/src/next/jdbc/sql.clj b/src/next/jdbc/sql.clj index b187116..882ddd3 100644 --- a/src/next/jdbc/sql.clj +++ b/src/next/jdbc/sql.clj @@ -82,9 +82,26 @@ columns and values to search on or a vector of a SQL where clause and parameters, returns a vector of hash maps of rows that match. + If `:all` is passed instead of a hash map or vector -- the query will + select all rows in the table, subject to any pagination options below. + + If `:columns` is passed, only that specified subset of columns will be + returned in each row (otherwise all columns are selected). + If the `:order-by` option is present, add an `ORDER BY` clause. `:order-by` should be a vector of column names or pairs of column name / direction, - which can be `:asc` or `:desc`." + which can be `:asc` or `:desc`. + + If the `:top` option is present, the SQL Server `SELECT TOP ?` syntax + is used and the value of the option is inserted as an additional parameter. + + If the `:limit` option is present, the MySQL `LIMIT ? OFFSET ?` syntax + is used (using the `:offset` option if present, else `OFFSET ?` is omitted). + PostgreSQL also supports this syntax. + + If the `:offset` option is present (without `:limit`), the standard + `OFFSET ? ROWS FETCH NEXT ? ROWS ONLY` syntax is used (using the `:fetch` + option if present, else `FETCH...` is omitted)." ([connectable table key-map] (find-by-keys connectable table key-map {})) ([connectable table key-map opts] @@ -98,7 +115,14 @@ a hash map of the first row that matches. By default, the primary key is assumed to be `id` but that can be overridden - in the five-argument call." + in the five-argument call. + + As with `find-by-keys`, you can specify `:columns` to return just a + subset of the columns in the returned row. + + Technically, this also supports `:order-by`, `:top`, `:limit`, `:offset`, + and `:fetch` -- like `find-by-keys` -- but they don't make as much sense + here since only one row is ever returned." ([connectable table pk] (get-by-id connectable table pk :id {})) ([connectable table pk opts] diff --git a/src/next/jdbc/sql/builder.clj b/src/next/jdbc/sql/builder.clj index 331d3e8..b2f7a5f 100644 --- a/src/next/jdbc/sql/builder.clj +++ b/src/next/jdbc/sql/builder.clj @@ -13,16 +13,46 @@ (defn as-? "Given a hash map of column names and values, or a vector of column names, return a string of `?` placeholders for them." - [key-map opts] + [key-map _] (str/join ", " (repeat (count key-map) "?"))) +(defn as-cols + "Given a sequence of raw column names, return a string of all the + formatted column names. + + If a raw column name is a keyword, apply `:column-fn` to its name, + from the options if present. + + If a raw column name is a vector pair, treat it as an expression with + an alias. If the first item is a keyword, apply `:column-fn` to its + name, else accept it as-is. The second item should be a keyword and + that will have `:column-fn` applied to its name. + + This allows columns to be specified as simple names, e.g., `:foo`, + as simple aliases, e.g., `[:foo :bar]`, or as expressions with an + alias, e.g., `[\"count(*)\" :total]`." + [cols opts] + (let [col-fn (:column-fn opts identity)] + (str/join ", " (map (fn [raw] + (if (vector? raw) + (if (keyword? (first raw)) + (str (col-fn (name (first raw))) + " AS " + (col-fn (name (second raw)))) + (str (first raw) + " AS " + (col-fn (name (second raw))))) + (col-fn (name raw)))) + cols)))) + + (defn as-keys "Given a hash map of column names and values, return a string of all the column names. Applies any `:column-fn` supplied in the options." [key-map opts] - (str/join ", " (map (comp (:column-fn opts identity) name) (keys key-map)))) + (as-cols (keys key-map) opts)) (defn by-keys "Given a hash map of column names and values and a clause type @@ -148,18 +178,49 @@ Applies any `:table-fn` / `:column-fn` supplied in the options. + Handles pagination options (`:top`, `:limit` / `:offset`, or `:offset` / + `:fetch`) for SQL Server, MySQL / SQLite, ANSI SQL respectively. + + By default, this selects all columns, but if the `:columns` option is + present the select will only be those columns. + If `:suffix` is provided in `opts`, that string is appended to the `SELECT ...` statement." [table where-params opts] (let [entity-fn (:table-fn opts identity) - where-params (if (map? where-params) - (by-keys where-params :where opts) - (into [(str "WHERE " (first where-params))] - (rest where-params)))] - (into [(str "SELECT * FROM " (entity-fn (name table)) - " " (first where-params) + where-params (cond (map? where-params) + (by-keys where-params :where opts) + (= :all where-params) + [nil] + :else + (into [(str "WHERE " (first where-params))] + (rest where-params))) + where-params (cond-> (if (:top opts) + (into [(first where-params)] + (cons (:top opts) (rest where-params))) + where-params) + (:limit opts) (conj (:limit opts)) + (:offset opts) (conj (:offset opts)) + (:fetch opts) (conj (:fetch opts)))] + (into [(str "SELECT " + (when (:top opts) + "TOP ? ") + (if-let [cols (seq (:columns opts))] + (as-cols cols opts) + "*") + " FROM " (entity-fn (name table)) + (when-let [clause (first where-params)] + (str " " clause)) (when-let [order-by (:order-by opts)] (str " " (for-order order-by opts))) + (when (:limit opts) + " LIMIT ?") + (when (:offset opts) + (if (:limit opts) + " OFFSET ?" + " OFFSET ? ROWS")) + (when (:fetch opts) + " FETCH NEXT ? ROWS ONLY") (when-let [suffix (:suffix opts)] (str " " suffix)))] (rest where-params)))) diff --git a/test/next/jdbc/middleware.clj b/test/next/jdbc/middleware.clj deleted file mode 100644 index c8e920a..0000000 --- a/test/next/jdbc/middleware.clj +++ /dev/null @@ -1,115 +0,0 @@ -;; copyright (c) 2019-2020 Sean Corfield, all rights reserved - -(ns next.jdbc.middleware - "This is just an experimental sketch of what it might look like to be - able to provide middleware that can wrap SQL execution in a way that - behavior can be extended in interesting ways, to support logging, timing. - and other cross-cutting things. - - Since it's just an experiment, there's no guarantee that this -- or - anything like it -- will actually end up in a next.jdbc release. You've - been warned! - - So far these execution points can be hooked into: - * start -- pre-process the SQL & parameters and options - * (execute SQL) - * ????? -- process the options (and something else?) - * row -- post-process each row and options - * rs -- post-process the whole result set and options - - For the rows and result set, it's 'obvious' that the functions should - take the values and return them (or updated versions). For the start - function with SQL & parameters, it also makes sense to take and return - that vector. - - For timing middleware, you'd need to pass data through the call chain - somehow -- unless you control the whole middleware and this isn't sufficient - for that yet. Hence the decision to allow processing of the options and - passing data through those -- which leads to a rather odd call chain: - start can return the vector or a map of updated options (with a payload), - and the ????? point can process the options again (e.g., to update timing - data etc). And that's all kind of horrible." - (:require [next.jdbc.protocols :as p] - [next.jdbc.result-set :as rs])) - -(defn post-processing-adapter - "Given a builder function (e.g., `as-lower-maps`), return a new builder - function that post-processes rows and the result set. The options may - contain post-processing functions that are called on each row and on the - the result set. The options map is provided as a second parameter to these - functions, which should include `:next.jdbc/sql-params` (the vector of SQL - and parameters, in case post-processing needs it): - - * `:execute-fn` -- called immediately after the SQL operation completes - ^ This is a horrible name and it needs to return the options which - is weird so I don't like this approach overall... - * `:row!-fn` -- called on each row as it is fully-realized - * `:rs!-fn` -- called on the whole result set once it is fully-realized - - The results of these functions are returned as the rows/result set." - [builder-fn] - (fn [rs opts] - (let [id2 (fn [x _] x) - id2' (fn [_ x] x) - exec-fn (get opts :execute-fn id2') - opts (exec-fn rs opts) - mrsb (builder-fn rs opts) - row!-fn (get opts :row!-fn id2) - rs!-fn (get opts :rs!-fn id2)] - (reify - rs/RowBuilder - (->row [this] (rs/->row mrsb)) - (column-count [this] (rs/column-count mrsb)) - (with-column [this row i] (rs/with-column mrsb row i)) - (row! [this row] (row!-fn (rs/row! mrsb row) opts)) - rs/ResultSetBuilder - (->rs [this] (rs/->rs mrsb)) - (with-row [this mrs row] (rs/with-row mrsb mrs row)) - (rs! [this mrs] (rs!-fn (rs/rs! mrsb mrs) opts)))))) - -(defrecord JdbcMiddleware [db global-opts] - p/Executable - (-execute [this sql-params opts] - (let [opts (merge global-opts opts) - id2 (fn [x _] x) - builder-fn (get opts :builder-fn rs/as-maps) - sql-params-fn (get opts :sql-params-fn id2) - result (sql-params-fn sql-params opts) - sql-params' (if (map? result) - (or (:next.jdbc/sql-params result) sql-params) - result)] - (p/-execute db sql-params' - (assoc (if (map? result) result opts) - :builder-fn (post-processing-adapter builder-fn) - :next.jdbc/sql-params sql-params')))) - (-execute-one [this sql-params opts] - (let [opts (merge global-opts opts) - id2 (fn [x _] x) - builder-fn (get opts :builder-fn rs/as-maps) - sql-params-fn (get opts :sql-params-fn id2) - result (sql-params-fn sql-params opts) - sql-params' (if (map? result) - (or (:next.jdbc/sql-params result) sql-params) - result)] - (p/-execute-one db sql-params' - (assoc (if (map? result) result opts) - :builder-fn (post-processing-adapter builder-fn) - :next.jdbc/sql-params sql-params')))) - (-execute-all [this sql-params opts] - (let [opts (merge global-opts opts) - id2 (fn [x _] x) - builder-fn (get opts :builder-fn rs/as-maps) - sql-params-fn (get opts :sql-params-fn id2) - result (sql-params-fn sql-params opts) - sql-params' (if (map? result) - (or (:next.jdbc/sql-params result) sql-params) - result)] - (p/-execute-all db sql-params' - (assoc (if (map? result) result opts) - :builder-fn (post-processing-adapter builder-fn) - :next.jdbc/sql-params sql-params'))))) - -(defn wrapper - "" - ([db] (JdbcMiddleware. db {})) - ([db opts] (JdbcMiddleware. db opts))) diff --git a/test/next/jdbc/middleware_test.clj b/test/next/jdbc/middleware_test.clj deleted file mode 100644 index cdc1319..0000000 --- a/test/next/jdbc/middleware_test.clj +++ /dev/null @@ -1,76 +0,0 @@ -;; copyright (c) 2019-2020 Sean Corfield, all rights reserved - -(ns next.jdbc.middleware-test - (:require [clojure.test :refer [deftest is use-fixtures]] - [next.jdbc :as jdbc] - [next.jdbc.middleware :as mw] - [next.jdbc.test-fixtures :refer [with-test-db db ds - default-options]] - [next.jdbc.result-set :as rs] - [next.jdbc.specs :as specs])) - -(set! *warn-on-reflection* true) - -(use-fixtures :once with-test-db) - -(specs/instrument) - -(deftest logging-test - (let [logging (atom []) - logger (fn [data _] (swap! logging conj data) data) - - sql-p ["select * from fruit where id in (?,?) order by id desc" 1 4]] - (jdbc/execute! (mw/wrapper (ds)) - sql-p - (assoc (default-options) - :builder-fn rs/as-lower-maps - :sql-params-fn logger - :row!-fn logger - :rs!-fn logger)) - ;; should log four things - (is (= 4 (-> @logging count))) - ;; :next.jdbc/sql-params value - (is (= sql-p (-> @logging (nth 0)))) - ;; first row (with PK 4) - (is (= 4 (-> @logging (nth 1) :fruit/id))) - ;; second row (with PK 1) - (is (= 1 (-> @logging (nth 2) :fruit/id))) - ;; full result set with two rows - (is (= 2 (-> @logging (nth 3) count))) - (is (= [4 1] (-> @logging (nth 3) (->> (map :fruit/id))))) - ;; now repeat without the row logging - (reset! logging []) - (jdbc/execute! (mw/wrapper (ds) - {:builder-fn rs/as-lower-maps - :sql-params-fn logger - :rs!-fn logger}) - sql-p - (default-options)) - ;; should log two things - (is (= 2 (-> @logging count))) - ;; :next.jdbc/sql-params value - (is (= sql-p (-> @logging (nth 0)))) - ;; full result set with two rows - (is (= 2 (-> @logging (nth 1) count))) - (is (= [4 1] (-> @logging (nth 1) (->> (map :fruit/id))))))) - -(deftest timing-test - (let [timing (atom {:calls 0 :total 0.0}) - start-fn (fn [_ opts] - (swap! (:timing opts) update :calls inc) - (assoc opts :start (System/nanoTime))) - exec-fn (fn [_ opts] - (let [end (System/nanoTime)] - (swap! (:timing opts) update :total + (- end (:start opts))) - opts)) - sql-p ["select * from fruit where id in (?,?) order by id desc" 1 4]] - (jdbc/execute! (mw/wrapper (ds) {:timing timing - :sql-params-fn start-fn - :execute-fn exec-fn}) - sql-p) - (jdbc/execute! (mw/wrapper (ds) {:timing timing - :sql-params-fn start-fn - :execute-fn exec-fn}) - sql-p) - (println (format "%6s %d calls took %,10d nanoseconds" - (:dbtype (db)) (:calls @timing) (long (:total @timing)))))) diff --git a/test/next/jdbc/sql/builder_test.clj b/test/next/jdbc/sql/builder_test.clj index 81dc4bf..82e6132 100644 --- a/test/next/jdbc/sql/builder_test.clj +++ b/test/next/jdbc/sql/builder_test.clj @@ -16,6 +16,14 @@ (is (= (builder/by-keys {:a nil :b 42 :c "s"} :set {}) ["SET a = ?, b = ?, c = ?" nil 42 "s"])))) +(deftest test-as-cols + (is (= (builder/as-cols [:a :b :c] {}) + "a, b, c")) + (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {}) + "a AS aa, b, count(*) AS c")) + (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {:column-fn mysql}) + "`a` AS `aa`, `b`, count(*) AS `c`"))) + (deftest test-as-keys (is (= (builder/as-keys {:a nil :b 42 :c "s"} {}) "a, b, c"))) @@ -44,7 +52,59 @@ ["id = ? and opt is null" 9] {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) [(str "SELECT * FROM [user] WHERE id = ? and opt is null" - " ORDER BY `a`, `b` DESC") 9])))) + " ORDER BY `a`, `b` DESC") 9]))) + (testing "by :all" + (is (= (builder/for-query + :user + :all + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) + ["SELECT * FROM [user] ORDER BY `a`, `b` DESC"]))) + (testing "top N" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]] + :top 42}) + ["SELECT TOP ? * FROM [user] WHERE `id` = ? ORDER BY `a`, `b` DESC" + 42 9]))) + (testing "limit" + (testing "without offset" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]] + :limit 42}) + [(str "SELECT * FROM [user] WHERE `id` = ?" + " ORDER BY `a`, `b` DESC LIMIT ?") + 9 42]))) + (testing "with offset" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]] + :limit 42 :offset 13}) + [(str "SELECT * FROM [user] WHERE `id` = ?" + " ORDER BY `a`, `b` DESC LIMIT ? OFFSET ?") + 9 42 13])))) + (testing "offset" + (testing "without fetch" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]] + :offset 13}) + [(str "SELECT * FROM [user] WHERE `id` = ?" + " ORDER BY `a`, `b` DESC OFFSET ? ROWS") + 9 13]))) + (testing "with fetch" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]] + :offset 13 :fetch 42}) + [(str "SELECT * FROM [user] WHERE `id` = ?" + " ORDER BY `a`, `b` DESC OFFSET ? ROWS FETCH NEXT ? ROWS ONLY") + 9 13 42]))))) (deftest test-for-delete (testing "by example" diff --git a/test/next/jdbc/sql_test.clj b/test/next/jdbc/sql_test.clj index c10473d..d19a879 100644 --- a/test/next/jdbc/sql_test.clj +++ b/test/next/jdbc/sql_test.clj @@ -8,6 +8,7 @@ [next.jdbc.sql :as sql] [next.jdbc.test-fixtures :refer [with-test-db ds column default-options + db derby? jtds? maria? mssql? mysql? postgres? sqlite?]] [next.jdbc.types :refer [as-other as-real as-varchar]])) @@ -26,6 +27,27 @@ (is (= 1 ((column :FRUIT/ID) (first rs)))) (is (= 4 ((column :FRUIT/ID) (last rs)))))) +(deftest test-find-all-offset + (let [ds-opts (jdbc/with-options (ds) (default-options)) + rs (sql/find-by-keys + ds-opts :fruit :all + (assoc + (if (or (mysql?) (sqlite?)) + {:limit 2 :offset 1} + {:offset 1 :fetch 2}) + :columns [:ID + ["CASE WHEN grade > 91 THEN 'ok ' ELSE 'bad' END" + :QUALITY]] + :order-by [:id]))] + (is (= 2 (count rs))) + (is (every? map? rs)) + (is (every? meta rs)) + (is (every? #(= 2 (count %)) rs)) + (is (= 2 ((column :FRUIT/ID) (first rs)))) + (is (= "ok " ((column :QUALITY) (first rs)))) + (is (= 3 ((column :FRUIT/ID) (last rs)))) + (is (= "bad" ((column :QUALITY) (last rs)))))) + (deftest test-find-by-keys (let [ds-opts (jdbc/with-options (ds) (default-options))] (let [rs (sql/find-by-keys ds-opts :fruit {:appearance "neon-green"})] diff --git a/test/next/jdbc/test_fixtures.clj b/test/next/jdbc/test_fixtures.clj index 0709a51..5b78806 100644 --- a/test/next/jdbc/test_fixtures.clj +++ b/test/next/jdbc/test_fixtures.clj @@ -21,9 +21,11 @@ (def ^:private test-sqlite {:dbtype "sqlite" :dbname "clojure_test_sqlite"}) ;; this is just a dummy db-spec -- it's handled in with-test-db below -(def ^:private test-postgres {:dbtype "embedded-postgres"}) +(def ^:private test-postgres-map {:dbtype "embedded-postgres"}) +(def ^:private test-postgres + (when-not (System/getenv "NEXT_JDBC_NO_POSTGRES") test-postgres-map)) ;; it takes a while to spin up so we kick it off at startup -(defonce embedded-pg (future (EmbeddedPostgres/start))) +(defonce embedded-pg (when test-postgres (future (EmbeddedPostgres/start)))) (def ^:private test-mysql-map (merge (if (System/getenv "NEXT_JDBC_TEST_MARIADB") @@ -47,9 +49,10 @@ (when (System/getenv "NEXT_JDBC_TEST_MSSQL") test-jtds-map)) (def ^:private test-db-specs - (cond-> [test-derby test-h2-mem test-h2 test-hsql test-sqlite test-postgres] - test-mysql (conj test-mysql) - test-mssql (conj test-mssql test-jtds))) + (cond-> [test-derby test-h2-mem test-h2 test-hsql test-sqlite] + test-postgres (conj test-postgres) + test-mysql (conj test-mysql) + test-mssql (conj test-mssql test-jtds))) (def ^:private test-db-spec (atom nil)) diff --git a/test/next/jdbc_test.clj b/test/next/jdbc_test.clj index 5851139..1f56663 100644 --- a/test/next/jdbc_test.clj +++ b/test/next/jdbc_test.clj @@ -2,7 +2,8 @@ (ns next.jdbc-test "Basic tests for the primary API of `next.jdbc`." - (:require [clojure.string :as str] + (:require [clojure.core.reducers :as r] + [clojure.string :as str] [clojure.test :refer [deftest is testing use-fixtures]] [next.jdbc :as jdbc] [next.jdbc.connection :as c] @@ -16,7 +17,8 @@ (set! *warn-on-reflection* true) -(use-fixtures :once with-test-db) +;; around each test because of the folding tests using 1,000 rows +(use-fixtures :each with-test-db) (specs/instrument) @@ -293,6 +295,57 @@ VALUES ('Pear', 'green', 49, 47) (is (= 4 (count (jdbc/execute! con ["select * from fruit"])))) (is (= ac (.getAutoCommit con))))))) +(deftest folding-test + (jdbc/execute-one! (ds) ["delete from fruit"]) + (with-open [con (jdbc/get-connection (ds)) + ps (jdbc/prepare con ["insert into fruit(name) values (?)"])] + (prep/execute-batch! ps (mapv #(vector (str "Fruit-" %)) (range 1 1001)))) + (testing "foldable result set" + (testing "from a Connection" + (let [result + (with-open [con (jdbc/get-connection (ds))] + (r/foldcat + (r/map (column :FRUIT/NAME) + (jdbc/plan con ["select * from fruit order by id"] + (default-options)))))] + (is (= 1000 (count result))) + (is (= "Fruit-1" (first result))) + (is (= "Fruit-1000" (last result))))) + (testing "from a DataSource" + (doseq [n [1 2 3 4 5 100 300 500 700 900 1000 1100]] + (testing (str "folding with n = " n) + (let [result + (r/fold n r/cat r/append! + (r/map (column :FRUIT/NAME) + (jdbc/plan (ds) ["select * from fruit order by id"] + (default-options))))] + (is (= 1000 (count result))) + (is (= "Fruit-1" (first result))) + (is (= "Fruit-1000" (last result))))))) + (testing "from a PreparedStatement" + (let [result + (with-open [con (jdbc/get-connection (ds)) + stmt (jdbc/prepare con + ["select * from fruit order by id"] + (default-options))] + (r/foldcat + (r/map (column :FRUIT/NAME) + (jdbc/plan stmt nil (default-options)))))] + (is (= 1000 (count result))) + (is (= "Fruit-1" (first result))) + (is (= "Fruit-1000" (last result))))) + (testing "from a Statement" + (let [result + (with-open [con (jdbc/get-connection (ds)) + stmt (prep/statement con (default-options))] + (r/foldcat + (r/map (column :FRUIT/NAME) + (jdbc/plan stmt ["select * from fruit order by id"] + (default-options)))))] + (is (= 1000 (count result))) + (is (= "Fruit-1" (first result))) + (is (= "Fruit-1000" (last result))))))) + (deftest connection-tests (testing "datasource via jdbcUrl" (when-not (postgres?)