Fixes #292 by supporting offset/fetch
This commit is contained in:
parent
6b070df52c
commit
82ee465820
6 changed files with 43 additions and 20 deletions
|
|
@ -8,7 +8,7 @@
|
|||
* Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`.
|
||||
* Add tests to confirm #299 does not affect v2.
|
||||
* Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293).
|
||||
* Add support for `SELECT TOP` (#292).
|
||||
* Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`.
|
||||
* Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2).
|
||||
* Fix #280 by adding `:escape` as special syntax for regular expression patterns.
|
||||
* Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order.
|
||||
|
|
|
|||
|
|
@ -570,18 +570,27 @@ user=> (sql/format {:select [:*] :from :table
|
|||
["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"]
|
||||
```
|
||||
|
||||
## limit, offset (MySQL)
|
||||
## limit, offset, fetch
|
||||
|
||||
Both `:limit` and `:offset` expect a single SQL expression:
|
||||
Some databases, including MySQL, support `:limit` and `:offset`
|
||||
for paginated queries, other databases support `:offset` and
|
||||
`fetch` for that (which is ANSI-compliant and should be
|
||||
preferred if your database supports it). All three expect a
|
||||
single SQL expression:
|
||||
|
||||
```clojure
|
||||
user=> (sql/format {:select [:id :name]
|
||||
:from [:table]
|
||||
:limit 20 :offset 20})
|
||||
["SELECT id, name FROM table LIMIT ? OFFSET ?" 20 20]
|
||||
:limit 10 :offset 20})
|
||||
["SELECT id, name FROM table LIMIT ? OFFSET ?" 10 20]
|
||||
user=> (sql/format {:select [:id :name]
|
||||
:from [:table]
|
||||
:offset 20 :fetch 10})
|
||||
["SELECT id, name FROM table OFFSET ? FETCH ? ONLY" 20 10]
|
||||
```
|
||||
|
||||
> Note: In the prerelease, these MySQL-specific clauses are in the default dialect but these will be moved to the `:mysql` dialect.
|
||||
All three are available in all dialects for HoneySQL so it
|
||||
is up to you to choose the correct pair for your database.
|
||||
|
||||
## for
|
||||
|
||||
|
|
@ -627,8 +636,6 @@ expected to be just one of those three mentioned above).
|
|||
The syntax accepted for MySQL's `:lock` is exactly the
|
||||
same as the `:for` clause above.
|
||||
|
||||
> Note: In the prerelease, this MySQL-specific clauses is in the default dialect but this will be moved to the `:mysql` dialect.
|
||||
|
||||
## values
|
||||
|
||||
`:values` accepts either a sequence of hash maps representing
|
||||
|
|
|
|||
|
|
@ -74,7 +74,7 @@ Other `honeysql.core` functions that no longer exist include: `build`, `qualify`
|
|||
|
||||
You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialect!` function (which sets a default dialect for all `format` operations) or by passing the new `:dialect` option to the `format` function. `:ansi` is the default dialect (which will mostly incorporate PostgreSQL usage over time). Other dialects supported are `:mysql` (which has a different quoting strategy and uses a different ranking for the `:set` clause), `:oracle` (which is essentially the `:ansi` dialect but will control other things over time), and `:sqlserver` (which is essentially the `:ansi` dialect but with a different quoting strategy). Other dialects and changes may be added over time.
|
||||
|
||||
> Note: `:limit` and `:offset` are currently in the default `:ansi` dialect even though they are MySQL-specific. This will change as the dialects are fleshed out. I plan to add `:top` for `:sqlserver` and `:offset` / `:fetch` for `:ansi`, at which point `:limit` / `:offset` will become MySQL-only.
|
||||
> Note: in general, all clauses are available in all dialects in HoneySQL unless the syntax of the clauses conflict between dialects (currently, no such clauses exist). The `:mysql` dialect is the only one so far that changes the priority ordering of a few clauses.
|
||||
|
||||
## Option Changes
|
||||
|
||||
|
|
|
|||
|
|
@ -259,8 +259,7 @@ The `:sqlserver` dialect uses `[`..`]` and the `:mysql` dialect uses
|
|||
```..```. In addition, the `:oracle` dialect disables `AS` in aliases.
|
||||
|
||||
Currently, the only dialect that has substantive differences from
|
||||
the others is `:mysql` which has a `:lock` clause (that is very
|
||||
similar to the ANSI `:for` clause) and for which the `:set` clause
|
||||
the others is `:mysql` for which the `:set` clause
|
||||
has a different precedence than ANSI SQL.
|
||||
|
||||
You can change the dialect globally using the `set-dialect!` function,
|
||||
|
|
|
|||
|
|
@ -53,7 +53,7 @@
|
|||
:cross-join
|
||||
:where :group-by :having
|
||||
:window :partition-by
|
||||
:order-by :limit :offset :for :values
|
||||
:order-by :limit :offset :fetch :for :lock :values
|
||||
:on-conflict :on-constraint :do-nothing :do-update-set :on-duplicate-key-update
|
||||
:returning
|
||||
:with-data])
|
||||
|
|
@ -79,14 +79,9 @@
|
|||
:sqlserver {:quote #(str \[ % \])}
|
||||
:mysql {:quote #(str \` % \`)
|
||||
:clause-order-fn (fn [order]
|
||||
;; :lock is like :for
|
||||
(swap! clause-format assoc :lock
|
||||
(get @clause-format :for))
|
||||
;; MySQL :set has different priority
|
||||
;; and :lock is between :for and :values
|
||||
(-> (filterv (complement #{:set}) order)
|
||||
(add-clause-before :set :where)
|
||||
(add-clause-before :lock :values)))}
|
||||
(add-clause-before :set :where)))}
|
||||
:oracle {:quote #(str \" % \") :as false}})
|
||||
|
||||
; should become defonce
|
||||
|
|
@ -778,7 +773,9 @@
|
|||
:order-by #'format-order-by
|
||||
:limit #'format-on-expr
|
||||
:offset #'format-on-expr
|
||||
:fetch #'format-on-expr
|
||||
:for #'format-lock-strength
|
||||
:lock #'format-lock-strength
|
||||
:values #'format-values
|
||||
:on-conflict #'format-on-conflict
|
||||
:on-constraint #'format-selector
|
||||
|
|
|
|||
|
|
@ -527,13 +527,18 @@
|
|||
(limit 40)
|
||||
|
||||
Produces: LIMIT ?
|
||||
Parameters: 40"
|
||||
Parameters: 40
|
||||
|
||||
The two-argument syntax is not supported: use `offset`
|
||||
instead:
|
||||
|
||||
`LIMIT 20,10` is equivalent to `LIMIT 10 OFFSET 20`"
|
||||
{:arglists '([limit])}
|
||||
[& args]
|
||||
(generic-1 :limit args))
|
||||
|
||||
(defn offset
|
||||
"Specific to MySQL, accepts a single SQL expression:
|
||||
"Accepts a single SQL expression:
|
||||
|
||||
(offset 10)
|
||||
|
||||
|
|
@ -543,10 +548,25 @@
|
|||
[& args]
|
||||
(generic-1 :offset args))
|
||||
|
||||
(defn fetch
|
||||
"Accepts a single SQL expression:
|
||||
|
||||
(fetch 10)
|
||||
|
||||
Produces: FETCH ? ONLY
|
||||
Parameters: 10"
|
||||
{:arglists '([offset])}
|
||||
[& args]
|
||||
(generic-1 :offset args))
|
||||
|
||||
(defn for
|
||||
[& args]
|
||||
(generic-1 :for args))
|
||||
|
||||
(defn lock
|
||||
[& args]
|
||||
(generic-1 :lock args))
|
||||
|
||||
(defn values
|
||||
"Accepts a single argument: a collection of row values.
|
||||
Each row value can be either a sequence of column values
|
||||
|
|
|
|||
Loading…
Reference in a new issue