address #281 add select * except / replace for BigQuery

This commit is contained in:
Sean Corfield 2022-01-06 23:02:20 -08:00
parent 499b9de0ae
commit a653f9b157
4 changed files with 75 additions and 20 deletions

View file

@ -1,6 +1,7 @@
# Changes # Changes
* 2.2.next in progress * 2.2.next in progress
* Address #281 by adding support for `SELECT * EXCEPT ..` and `SELECT * REPLACE ..` -- see [SQL Clause Reference - SELECT](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started/sql-clause-reference#select-select-distinct) for more details.
* Update `build-clj` to v0.6.7. * Update `build-clj` to v0.6.7.
* 2.2.840 -- 2021-12-23 * 2.2.840 -- 2021-12-23

View file

@ -348,8 +348,16 @@ third is a simple column name and its alias.
`:select-distinct` works the same way but produces `SELECT DISTINCT`. `:select-distinct` works the same way but produces `SELECT DISTINCT`.
HoneySQL does not yet support `SELECT .. INTO ..` > 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:
or `SELECT .. BULK COLLECT INTO ..`.
```clojure
user=> (sql/format {:select [[:* :except [:a :b :c]]] :from [:table]})
["SELECT * EXCEPT (a, b, c) FROM table"]
user=> (sql/format {:select [[:* :replace [[[:* :a [:inline 100]] :b] [[:inline 2] :c]]]] :from [:table]})
["SELECT * REPLACE (a * 100 AS b, 2 AS c) FROM table"]
user=> (sql/format {:select [[:* :except [:a :b] :replace [[[:inline 2] :c]]]] :from [:table]})
["SELECT * EXCEPT (a, b) REPLACE (2 AS c) FROM table"]
```
## select-distinct-on ## select-distinct-on

View file

@ -294,30 +294,63 @@
:else :else
(format-entity x))) (format-entity x)))
(declare format-selects-common)
(defn- format-selectable-dsl [x & [{:keys [as aliased] :as opts}]] (defn- format-selectable-dsl [x & [{:keys [as aliased] :as opts}]]
(cond (map? x) (cond (map? x)
(format-dsl x {:nested true}) (format-dsl x {:nested true})
(sequential? x) (sequential? x)
(let [s (first x) (let [s (first x)
pair? (< 1 (count x))
a (second x) a (second x)
pair? (= 2 (count x))
big? (and (ident? s) (= "*" (name s))
(ident? a) (#{"except" "replace"} (name a)))
more? (and (< 2 (count x)) (not big?))
[sql & params] (if (map? s) [sql & params] (if (map? s)
(format-dsl s {:nested true}) (format-dsl s {:nested true})
(format-expr s)) (format-expr s))
[sql' & params'] (when pair? [sql' & params'] (when (or pair? big?)
(if (sequential? a) (cond (sequential? a)
(let [[sql params] (format-expr-list a {:aliased true})] (let [[sqls params] (format-expr-list a {:aliased true})]
(into [(str/join " " sql)] params)) (into [(str/join " " sqls)] params))
(format-selectable-dsl a {:aliased true})))] big? ; BigQuery support #281
(-> [(cond-> sql (reduce (fn [[sql & params] [k arg]]
pair? (let [[sql' params']
(str (if as (cond (and (ident? k) (= "except" (name k)) arg)
(if (and (contains? *dialect* :as) (let [[sqls params]
(not (:as *dialect*))) (format-expr-list arg {:aliased true})]
" " [(str (sql-kw k) " (" (str/join ", " sqls) ")")
" AS ") params])
" ") sql'))] (and (ident? k) (= "replace" (name k)) arg)
(let [[sql & params] (format-selects-common nil true arg)]
[(str (sql-kw k) " (" sql ")")
params])
:else
(throw (ex-info "bigquery * only supports except and replace"
{:clause k :arg arg})))]
(-> [(cond->> sql' sql (str sql " "))]
(into params)
(into params'))))
[]
(partition-all 2 (rest x)))
:else
(format-selectable-dsl a {:aliased true})))]
(-> [(cond pair?
(str sql
(if as
(if (and (contains? *dialect* :as)
(not (:as *dialect*)))
" "
" AS ")
" ") sql')
big?
(str sql " " sql')
more?
(throw (ex-info "illegal syntax in select expression"
{:symbol s :alias a :unexpected (nnext x)}))
:else
sql)]
(into params) (into params)
(into params'))) (into params')))
@ -376,9 +409,9 @@
(when (empty? xs) (when (empty? xs)
(throw (ex-info (str prefix " empty column list is illegal") (throw (ex-info (str prefix " empty column list is illegal")
{:clause (into [prefix] xs)})))) {:clause (into [prefix] xs)}))))
(into [(str prefix " " (str/join ", " sqls))] params)) (into [(str (when prefix (str prefix " ")) (str/join ", " sqls))] params))
(let [[sql & params] (format-selectable-dsl xs {:as as})] (let [[sql & params] (format-selectable-dsl xs {:as as})]
(into [(str prefix " " sql)] params)))) (into [(str (when prefix (str prefix " ")) sql)] params))))
(defn- format-selects [k xs] (defn- format-selects [k xs]
(format-selects-common (format-selects-common

View file

@ -3,7 +3,8 @@
(ns honey.bigquery-test (ns honey.bigquery-test
(:refer-clojure :exclude [format]) (:refer-clojure :exclude [format])
(:require [clojure.test :refer [deftest is]] (:require [clojure.test :refer [deftest is]]
[honey.sql :as sut])) [honey.sql :as sut])
#?(:clj (:import (clojure.lang ExceptionInfo))))
(deftest except-replace-tests (deftest except-replace-tests
(is (= ["SELECT * FROM table WHERE id = ?" 1] (is (= ["SELECT * FROM table WHERE id = ?" 1]
@ -13,4 +14,16 @@
(is (= ["SELECT * REPLACE (a * 100 AS b, 2 AS c) FROM table WHERE id = ?" 1] (is (= ["SELECT * REPLACE (a * 100 AS b, 2 AS c) FROM table WHERE id = ?" 1]
(sut/format {:select [[:* :replace [[[:* :a [:inline 100]] :b] [[:inline 2] :c]]]] :from [:table] :where [:= :id 1]}))) (sut/format {:select [[:* :replace [[[:* :a [:inline 100]] :b] [[:inline 2] :c]]]] :from [:table] :where [:= :id 1]})))
(is (= ["SELECT * EXCEPT (a, b) REPLACE (2 AS c) FROM table WHERE id = ?" 1] (is (= ["SELECT * EXCEPT (a, b) REPLACE (2 AS c) FROM table WHERE id = ?" 1]
(sut/format {:select [[:* :except [:a :b] :replace [[[:inline 2] :c]]]] :from [:table] :where [:= :id 1]})))) (sut/format {:select [[:* :except [:a :b] :replace [[[:inline 2] :c]]]] :from [:table] :where [:= :id 1]})))
(is (= ["SELECT * REPLACE (a * ? AS b, ? AS c) FROM table WHERE id = ?" 100 2 1]
(sut/format {:select [[:* :replace [[[:* :a 100] :b] [2 :c]]]] :from [:table] :where [:= :id 1]})))
(is (= ["SELECT * EXCEPT (a, b) REPLACE (? AS c) FROM table WHERE id = ?" 2 1]
(sut/format {:select [[:* :except [:a :b] :replace [[2 :c]]]] :from [:table] :where [:= :id 1]}))))
(deftest bad-select-tests
(is (thrown? ExceptionInfo
(sut/format {:select [[:* :except [:a] :bad]]})))
(is (thrown? ExceptionInfo
(sut/format {:select [[:* :except]]})))
(is (thrown? ExceptionInfo
(sut/format {:select [[:foo :bar :quux]]}))))