Address #124 by adding support for top/limit/offset/fetch

Also allows find where clause to be nil/empty (instead of generating 
invalid SQL).
This commit is contained in:
Sean Corfield 2020-06-24 18:55:08 -07:00
parent 2e1e11c025
commit 5b15215f83
4 changed files with 105 additions and 7 deletions

View file

@ -2,6 +2,9 @@
Only accretive/fixative changes will be made from now on.
Changes made since the 1.0.478 release:
* Address #124 by extending `next.jdbc.sql.builder/for-query` to support `:top` (SQL Server), `:limit` / `:offset` (MySQL/PostgreSQL), `:offset` / `:fetch` (SQL Standard).
## Stable Builds
* 2020-06-24 -- 1.0.478

View file

@ -82,9 +82,23 @@
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 the vector is empty -- no SQL and no parameters -- the query will
select all rows in the table: be warned!
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 +112,11 @@
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.
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

@ -154,12 +154,32 @@
(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)
(into [(when-let [clause (first where-params)]
(str "WHERE " clause))]
(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 ? ")
"* 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

@ -44,7 +44,64 @@
["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 "with nil where clause"
(is (= (builder/for-query
:user
nil
{:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]})
["SELECT * FROM [user] ORDER BY `a`, `b` DESC"]))
(is (= (builder/for-query
:user
[nil]
{: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"