fix #512 by supporting array subquery
also adds metadata support for select to produce as struct (or distinct)
This commit is contained in:
parent
b3fe7c1436
commit
737baa9d0e
6 changed files with 110 additions and 28 deletions
|
|
@ -1,6 +1,7 @@
|
||||||
# Changes
|
# Changes
|
||||||
|
|
||||||
* 2.4.next in progress
|
* 2.4.next in progress
|
||||||
|
* Address [#512](https://github.com/seancorfield/honeysql/issues/512) by adding support for subqueries in the `:array` special syntax (for BigQuery and PostgreSQL). This also adds support for metadata on the `:select` value to produce `AS STRUCT` or `DISTINCT`.
|
||||||
* Address [#511](https://github.com/seancorfield/honeysql/issues/511) by adding support for BigQuery `CREATE OR REPLACE`.
|
* Address [#511](https://github.com/seancorfield/honeysql/issues/511) by adding support for BigQuery `CREATE OR REPLACE`.
|
||||||
* Address [#510](https://github.com/seancorfield/honeysql/issues/510) by adding initial support for an NRQL dialect.
|
* Address [#510](https://github.com/seancorfield/honeysql/issues/510) by adding initial support for an NRQL dialect.
|
||||||
* Fix [#509](https://github.com/seancorfield/honeysql/issues/509) by checking for `ident?` before checking keyword/symbol.
|
* Fix [#509](https://github.com/seancorfield/honeysql/issues/509) by checking for `ident?` before checking keyword/symbol.
|
||||||
|
|
|
||||||
|
|
@ -509,6 +509,23 @@ name reference.
|
||||||
|
|
||||||
`:select-distinct` works the same way but produces `SELECT DISTINCT`.
|
`:select-distinct` works the same way but produces `SELECT DISTINCT`.
|
||||||
|
|
||||||
|
As of 2.4.next, you can use metadata on the argument to `:select` to
|
||||||
|
provide qualifiers for the `SELECT` clause:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
user=> (sql/format {:select ^:distinct [:id :name] :from :table})
|
||||||
|
["SELECT DISTINCT id, name FROM table"]
|
||||||
|
```
|
||||||
|
|
||||||
|
The metadata can also be a map, with `true` values ignored (which is why
|
||||||
|
`^:distinct` produces just `DISTINCT` even though it is short for
|
||||||
|
`^{:distinct true}`):
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
user=> (sql/format {:select ^{:as :struct} [:id :name] :from :table})
|
||||||
|
["SELECT AS STRUCT id, name FROM table"]
|
||||||
|
```
|
||||||
|
|
||||||
> Google BigQuery support: to provide `SELECT * EXCEPT ..` and `SELECT * REPLACE ..` syntax, HoneySQL supports a vector starting with `:*` or the symbol `*` followed by except columns and/or replace expressions as columns:
|
> Google BigQuery support: to provide `SELECT * EXCEPT ..` and `SELECT * REPLACE ..` syntax, HoneySQL supports a vector starting with `:*` or the symbol `*` followed by except columns and/or replace expressions as columns:
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
|
|
|
||||||
|
|
@ -37,14 +37,27 @@ Clojure users can opt for the shorter `(require '[honey.sql :as sql] '[honey.sql
|
||||||
|
|
||||||
## Working with Arrays
|
## Working with Arrays
|
||||||
|
|
||||||
HoneySQL supports `:array` as special syntax to produce `ARRAY[..]` expressions
|
HoneySQL supports `:array` as special syntax to produce `ARRAY[..]` expressions:
|
||||||
but PostgreSQL also has an "array constructor" for creating arrays from subquery results.
|
|
||||||
|
```clojure
|
||||||
|
user=> (sql/format {:select [[[:array [1 2 3]] :a]]})
|
||||||
|
["SELECT ARRAY[?, ?, ?] AS a" 1 2 3]
|
||||||
|
```
|
||||||
|
|
||||||
|
PostgreSQL also has an "array constructor" for creating arrays from subquery results.
|
||||||
|
|
||||||
```sql
|
```sql
|
||||||
SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%');
|
SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%');
|
||||||
```
|
```
|
||||||
|
|
||||||
In order to produce that SQL, you can use HoneySQL's "as-is" function syntax to circumvent
|
As of 2.4.next, HoneySQL supports this syntax directly:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
user=> (sql/format {:select [[[:array {:select :oid :from :pg_proc :where [:like :proname [:inline "bytea%"]]}]]]})
|
||||||
|
["SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%')"]
|
||||||
|
```
|
||||||
|
|
||||||
|
Prior to 2.4.next, you had to use HoneySQL's "as-is" function syntax to circumvent
|
||||||
the special syntax:
|
the special syntax:
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
|
|
@ -52,13 +65,6 @@ user=> (sql/format {:select [[[:'ARRAY {:select :oid :from :pg_proc :where [:lik
|
||||||
["SELECT ARRAY (SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%')"]
|
["SELECT ARRAY (SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%')"]
|
||||||
```
|
```
|
||||||
|
|
||||||
Compare this with the `ARRAY[..]` syntax:
|
|
||||||
|
|
||||||
```clojure
|
|
||||||
user=> (sql/format {:select [[[:array [1 2 3]] :a]]})
|
|
||||||
["SELECT ARRAY[?, ?, ?] AS a" 1 2 3]
|
|
||||||
```
|
|
||||||
|
|
||||||
## Operators with @, #, and ~
|
## Operators with @, #, and ~
|
||||||
|
|
||||||
A number of PostgreSQL operators contain `@`, `#`, or `~` which are not legal in a Clojure keyword or symbol (as literal syntax). The namespace `honey.sql.pg-ops` provides convenient symbolic names for these JSON and regex operators, substituting `at` for `@`, `hash` for `#`, and `tilde` for `~`.
|
A number of PostgreSQL operators contain `@`, `#`, or `~` which are not legal in a Clojure keyword or symbol (as literal syntax). The namespace `honey.sql.pg-ops` provides convenient symbolic names for these JSON and regex operators, substituting `at` for `@`, `hash` for `#`, and `tilde` for `~`.
|
||||||
|
|
|
||||||
|
|
@ -33,9 +33,14 @@ and strings.
|
||||||
|
|
||||||
## array
|
## array
|
||||||
|
|
||||||
Accepts a single argument, which is expected to evaluate to a sequence,
|
Accepts either an expression (that evaluates to a sequence) or a subquery
|
||||||
with an optional second argument specifying the type of the array,
|
(hash map). In the expression case, also accepts an optional second argument
|
||||||
and produces `ARRAY[?, ?, ..]` for the elements of that sequence (as SQL parameters):
|
that specifies the type of the array.
|
||||||
|
|
||||||
|
Produces either an `ARRAY[..]` or an `ARRAY(subquery)` expression.
|
||||||
|
|
||||||
|
In the expression case, produces `ARRAY[?, ?, ..]` for the elements of that
|
||||||
|
sequence (as SQL parameters):
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
(sql/format-expr [:array (range 5)])
|
(sql/format-expr [:array (range 5)])
|
||||||
|
|
@ -68,6 +73,13 @@ In addition, the argument to `:array` is treated as a literal sequence of Clojur
|
||||||
;;=> ["SELECT ARRAY[inline, (?, ?, ?)] AS arr" 1 2 3]
|
;;=> ["SELECT ARRAY[inline, (?, ?, ?)] AS arr" 1 2 3]
|
||||||
```
|
```
|
||||||
|
|
||||||
|
In the subquery case, produces `ARRAY(subquery)`:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
(sql/format {:select [[[:array {:select :* :from :table}] :arr]]})
|
||||||
|
;;=> ["SELECT ARRAY(SELECT * FROM table) AS arr"]
|
||||||
|
```
|
||||||
|
|
||||||
## at time zone
|
## at time zone
|
||||||
|
|
||||||
Accepts two arguments: an expression (assumed to be a date/time of some sort)
|
Accepts two arguments: an expression (assumed to be a date/time of some sort)
|
||||||
|
|
|
||||||
|
|
@ -664,16 +664,41 @@
|
||||||
(let [[sqls params] (format-expr-list xs {:drop-ns true})]
|
(let [[sqls params] (format-expr-list xs {:drop-ns true})]
|
||||||
(into [(str "(" (str/join ", " sqls) ")")] params))))
|
(into [(str "(" (str/join ", " sqls) ")")] params))))
|
||||||
|
|
||||||
|
(defn- format-meta
|
||||||
|
"If the expression has metadata, format it as a sequence of keywords,
|
||||||
|
treating `:foo true` as `FOO` and `:foo :bar` as `FOO BAR`.
|
||||||
|
Return nil if there is no metadata."
|
||||||
|
[x]
|
||||||
|
(when-let [data (meta x)]
|
||||||
|
(let [items (reduce-kv (fn [acc k v]
|
||||||
|
(if (true? v)
|
||||||
|
(conj acc k)
|
||||||
|
(conj acc k v)))
|
||||||
|
[]
|
||||||
|
(apply dissoc data [:line :column]))]
|
||||||
|
(when (seq items)
|
||||||
|
(println "items" items)
|
||||||
|
(str/join " " (mapv sql-kw items))))))
|
||||||
|
|
||||||
|
(comment
|
||||||
|
(format-meta ^{:foo true :bar :baz} [])
|
||||||
|
(format-meta [])
|
||||||
|
)
|
||||||
|
|
||||||
(defn- format-selects-common [prefix as xs]
|
(defn- format-selects-common [prefix as xs]
|
||||||
(if (sequential? xs)
|
(let [qualifier (format-meta xs)
|
||||||
(let [[sqls params] (reduce-sql (map #(format-selectable-dsl % {:as as}) xs))]
|
prefix (if prefix
|
||||||
(when-not (= :none *checking*)
|
(cond-> prefix qualifier (str " " qualifier))
|
||||||
(when (empty? xs)
|
qualifier)]
|
||||||
(throw (ex-info (str prefix " empty column list is illegal")
|
(if (sequential? xs)
|
||||||
{:clause (into [prefix] xs)}))))
|
(let [[sqls params] (reduce-sql (map #(format-selectable-dsl % {:as as}) xs))]
|
||||||
(into [(str (when prefix (str prefix " ")) (str/join ", " sqls))] params))
|
(when-not (= :none *checking*)
|
||||||
(let [[sql & params] (format-selectable-dsl xs {:as as})]
|
(when (empty? xs)
|
||||||
(into [(str (when prefix (str prefix " ")) sql)] params))))
|
(throw (ex-info (str prefix " empty column list is illegal")
|
||||||
|
{:clause (into [prefix] xs)}))))
|
||||||
|
(into [(str (when prefix (str prefix " ")) (str/join ", " sqls))] params))
|
||||||
|
(let [[sql & params] (format-selectable-dsl xs {:as as})]
|
||||||
|
(into [(str (when prefix (str prefix " ")) sql)] params)))))
|
||||||
|
|
||||||
(defn- format-selects [k xs]
|
(defn- format-selects [k xs]
|
||||||
(format-selects-common
|
(format-selects-common
|
||||||
|
|
@ -1699,10 +1724,14 @@
|
||||||
">")])
|
">")])
|
||||||
:array
|
:array
|
||||||
(fn [_ [arr type]]
|
(fn [_ [arr type]]
|
||||||
;; allow for (unwrap arr) here?
|
;; #512 allow for subquery here:
|
||||||
(let [[sqls params] (format-expr-list arr)
|
(if (map? arr)
|
||||||
type-str (when type (str "::" (sql-kw type) "[]"))]
|
(let [[sql & params] (format-dsl arr)]
|
||||||
(into [(str "ARRAY[" (str/join ", " sqls) "]" type-str)] params)))
|
(into [(str "ARRAY(" sql ")")] params))
|
||||||
|
;; allow for (unwrap arr) here?
|
||||||
|
(let [[sqls params] (format-expr-list arr)
|
||||||
|
type-str (when type (str "::" (sql-kw type) "[]"))]
|
||||||
|
(into [(str "ARRAY[" (str/join ", " sqls) "]" type-str)] params))))
|
||||||
:at-time-zone
|
:at-time-zone
|
||||||
(fn [_ [expr tz]]
|
(fn [_ [expr tz]]
|
||||||
(let [[sql & params] (format-expr expr {:nested true})
|
(let [[sql & params] (format-expr expr {:nested true})
|
||||||
|
|
@ -2348,5 +2377,5 @@
|
||||||
:since [2 :days :ago]
|
:since [2 :days :ago]
|
||||||
:limit 2000}
|
:limit 2000}
|
||||||
{:dialect :nrql :pretty true})
|
{:dialect :nrql :pretty true})
|
||||||
|
(sql/format {:select [[[:array {:select :* :from :table}] :arr]]})
|
||||||
)
|
)
|
||||||
|
|
|
||||||
|
|
@ -296,7 +296,15 @@
|
||||||
(is (= (format {:select [[[:array [] :integer]]]})
|
(is (= (format {:select [[[:array [] :integer]]]})
|
||||||
["SELECT ARRAY[]::INTEGER[]"]))
|
["SELECT ARRAY[]::INTEGER[]"]))
|
||||||
(is (= (format {:select [[[:array [1 2] :text]]]})
|
(is (= (format {:select [[[:array [1 2] :text]]]})
|
||||||
["SELECT ARRAY[?, ?]::TEXT[]" 1 2]))))
|
["SELECT ARRAY[?, ?]::TEXT[]" 1 2])))
|
||||||
|
(testing "array subquery"
|
||||||
|
(is (= (format {:select [[[:array {:select [:foo] :from [:bar]}]]]})
|
||||||
|
["SELECT ARRAY(SELECT foo FROM bar)"]))
|
||||||
|
(is (= (format {:select [[[:array {:select ^{:as :struct} [:foo :bar] :from [:bar]}]]]})
|
||||||
|
["SELECT ARRAY(SELECT AS STRUCT foo, bar FROM bar)"]))
|
||||||
|
;; documented subquery workaround:
|
||||||
|
(is (= (format {:select [[[:'ARRAY {:select [:foo] :from [:bar]}]]]})
|
||||||
|
["SELECT ARRAY (SELECT foo FROM bar)"]))))
|
||||||
|
|
||||||
(deftest union-test
|
(deftest union-test
|
||||||
;; UNION and INTERSECT subexpressions should not be parenthesized.
|
;; UNION and INTERSECT subexpressions should not be parenthesized.
|
||||||
|
|
@ -1276,6 +1284,15 @@ ORDER BY id = ? DESC
|
||||||
(is (= ["INSERT INTO table VALUES (?)" unhashable]
|
(is (= ["INSERT INTO table VALUES (?)" unhashable]
|
||||||
(sut/format {:insert-into :table :values [[unhashable]]})))))
|
(sut/format {:insert-into :table :values [[unhashable]]})))))
|
||||||
|
|
||||||
|
(deftest issue-512
|
||||||
|
(testing "select with metadata"
|
||||||
|
(is (= ["SELECT DISTINCT * FROM table"]
|
||||||
|
(sut/format {:select-distinct [:*] :from [:table]})))
|
||||||
|
(is (= ["SELECT DISTINCT * FROM table"]
|
||||||
|
(sut/format {:select ^{:distinct true} [:*] :from [:table]})))
|
||||||
|
(is (= ["SELECT DISTINCT * FROM table"]
|
||||||
|
(sut/format {:select ^:distinct [:*] :from [:table]})))))
|
||||||
|
|
||||||
(comment
|
(comment
|
||||||
;; partial workaround for #407:
|
;; partial workaround for #407:
|
||||||
(sut/format {:select :f.* :from [[:foo [:f :for :system-time]]] :where [:= :f.id 1]})
|
(sut/format {:select :f.* :from [[:foo [:f :for :system-time]]] :where [:= :f.id 1]})
|
||||||
|
|
|
||||||
Loading…
Reference in a new issue