Skip to content

Commit

Permalink
fix #512 by supporting array subquery
Browse files Browse the repository at this point in the history
also adds metadata support for select to produce as struct (or distinct)
  • Loading branch information
seancorfield committed Oct 28, 2023
1 parent b3fe7c1 commit 737baa9
Show file tree
Hide file tree
Showing 6 changed files with 109 additions and 27 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
# Changes

* 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 [#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.
Expand Down
17 changes: 17 additions & 0 deletions doc/clause-reference.md
Original file line number Diff line number Diff line change
Expand Up @@ -509,6 +509,23 @@ name reference.

`: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:
```clojure
Expand Down
24 changes: 15 additions & 9 deletions doc/postgresql.md
Original file line number Diff line number Diff line change
Expand Up @@ -37,26 +37,32 @@ Clojure users can opt for the shorter `(require '[honey.sql :as sql] '[honey.sql

## Working with Arrays

HoneySQL supports `:array` as special syntax to produce `ARRAY[..]` expressions
but PostgreSQL also has an "array constructor" for creating arrays from subquery results.
HoneySQL supports `:array` as special syntax to produce `ARRAY[..]` expressions:

```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
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
the special syntax:
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%')"]
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%')"]
```

Compare this with the `ARRAY[..]` syntax:
Prior to 2.4.next, you had to use HoneySQL's "as-is" function syntax to circumvent
the special syntax:

```clojure
user=> (sql/format {:select [[[:array [1 2 3]] :a]]})
["SELECT ARRAY[?, ?, ?] AS a" 1 2 3]
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%')"]
```

## Operators with @, #, and ~
Expand Down
18 changes: 15 additions & 3 deletions doc/special-syntax.md
Original file line number Diff line number Diff line change
Expand Up @@ -33,9 +33,14 @@ and strings.

## array

Accepts a single argument, which is expected to evaluate to a sequence,
with an optional second argument specifying the type of the array,
and produces `ARRAY[?, ?, ..]` for the elements of that sequence (as SQL parameters):
Accepts either an expression (that evaluates to a sequence) or a subquery
(hash map). In the expression case, also accepts an optional second argument
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
(sql/format-expr [:array (range 5)])
Expand Down Expand Up @@ -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]
```

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

Accepts two arguments: an expression (assumed to be a date/time of some sort)
Expand Down
57 changes: 43 additions & 14 deletions src/honey/sql.cljc
Original file line number Diff line number Diff line change
Expand Up @@ -664,16 +664,41 @@
(let [[sqls params] (format-expr-list xs {:drop-ns true})]
(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]
(if (sequential? xs)
(let [[sqls params] (reduce-sql (map #(format-selectable-dsl % {:as as}) xs))]
(when-not (= :none *checking*)
(when (empty? xs)
(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))))
(let [qualifier (format-meta xs)
prefix (if prefix
(cond-> prefix qualifier (str " " qualifier))
qualifier)]
(if (sequential? xs)
(let [[sqls params] (reduce-sql (map #(format-selectable-dsl % {:as as}) xs))]
(when-not (= :none *checking*)
(when (empty? xs)
(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]
(format-selects-common
Expand Down Expand Up @@ -1699,10 +1724,14 @@
">")])
:array
(fn [_ [arr type]]
;; 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)))
;; #512 allow for subquery here:
(if (map? arr)
(let [[sql & params] (format-dsl arr)]
(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
(fn [_ [expr tz]]
(let [[sql & params] (format-expr expr {:nested true})
Expand Down Expand Up @@ -2348,5 +2377,5 @@
:since [2 :days :ago]
:limit 2000}
{:dialect :nrql :pretty true})

(sql/format {:select [[[:array {:select :* :from :table}] :arr]]})
)
19 changes: 18 additions & 1 deletion test/honey/sql_test.cljc
Original file line number Diff line number Diff line change
Expand Up @@ -296,7 +296,15 @@
(is (= (format {:select [[[:array [] :integer]]]})
["SELECT ARRAY[]::INTEGER[]"]))
(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
;; UNION and INTERSECT subexpressions should not be parenthesized.
Expand Down Expand Up @@ -1276,6 +1284,15 @@ ORDER BY id = ? DESC
(is (= ["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
;; partial workaround for #407:
(sut/format {:select :f.* :from [[:foo [:f :for :system-time]]] :where [:= :f.id 1]})
Expand Down

0 comments on commit 737baa9

Please sign in to comment.