Merge branch 'develop' into multi-rs

This commit is contained in:
Sean Corfield 2020-06-25 19:12:11 -07:00
commit a66e87aed0
8 changed files with 242 additions and 15 deletions

View file

@ -2,8 +2,11 @@
Only accretive/fixative changes will be made from now on.
Changes made on master since 1.0.476:
Changes made since the 1.0.478 release:
* WIP: support for stored procedures and multiple result sets!
* 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

View file

@ -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:

View file

@ -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`

View file

@ -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

View file

@ -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]

View file

@ -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))))

View file

@ -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"

View file

@ -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"})]