Merge pull request #376 from seancorfield/except-replace-issue-281
BigQuery Support (except/replace)
This commit is contained in:
commit
91e054c58b
5 changed files with 156 additions and 20 deletions
|
|
@ -1,6 +1,8 @@
|
|||
# Changes
|
||||
|
||||
* 2.2.next in progress
|
||||
* Address #377 by adding `honey.sql/map=` to convert a hash map into an equality condition (for a `WHERE` clause).
|
||||
* Address #281 by adding support for `SELECT * EXCEPT ..` and `SELECT * REPLACE ..` and `ARRAY<>` and `STRUCT<>` column types -- see [SQL Clause Reference - SELECT](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started/sql-clause-reference#select-select-distinct) and [SQL Clause Reference - DDL](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started/sql-clause-reference#ddl-clauses) respectively for more details.
|
||||
* Update `build-clj` to v0.6.7.
|
||||
|
||||
* 2.2.840 -- 2021-12-23
|
||||
|
|
|
|||
|
|
@ -30,6 +30,8 @@ Several of these include column specifications and HoneySQL
|
|||
provides some special syntax (functions) to support that.
|
||||
See [Column Descriptors in Special Syntax](special-syntax.md#column-descriptors) for more details.
|
||||
|
||||
> Google BigQuery support: `[:bigquery/array :string]` as a column type produces `ARRAY<STRING>` and `[:bigquery/struct col1-spec col2-spec]` as a column type produces `STRUCT<col1, col2>` (where `colN-spec` is a vector specifying a named column).
|
||||
|
||||
## alter-table, add-column, drop-column, modify-column, rename-column
|
||||
|
||||
`:alter-table` can accept either a single table name or
|
||||
|
|
@ -348,8 +350,16 @@ third is a simple column name and its alias.
|
|||
|
||||
`:select-distinct` works the same way but produces `SELECT DISTINCT`.
|
||||
|
||||
HoneySQL does not yet support `SELECT .. INTO ..`
|
||||
or `SELECT .. BULK COLLECT 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:
|
||||
|
||||
```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
|
||||
|
||||
|
|
@ -664,6 +674,17 @@ The `:where` clause can have a single SQL expression, or
|
|||
a sequence of SQL expressions prefixed by either `:and`
|
||||
or `:or`. See examples of `:where` in various clauses above.
|
||||
|
||||
Sometimes it is convenient to construct a `WHERE` clause that
|
||||
tests several columns for equality, and you might have a Clojure
|
||||
hash map containing those values. `honey.sql/map=` exists to
|
||||
convert a hash map of values into a condition that you can use
|
||||
in a `WHERE` clause to match against those columns and values:
|
||||
|
||||
```clojure
|
||||
user=> (sql/format {:select :* :from :transaction :where (sql/map= {:type "sale" :productid 123})})
|
||||
["SELECT * FROM transaction WHERE (type = ?) AND (productid = ?)" "sale" 123]
|
||||
```
|
||||
|
||||
## group-by
|
||||
|
||||
`:group-by` accepts a sequence of one or more SQL expressions.
|
||||
|
|
|
|||
|
|
@ -294,30 +294,63 @@
|
|||
:else
|
||||
(format-entity x)))
|
||||
|
||||
(declare format-selects-common)
|
||||
|
||||
(defn- format-selectable-dsl [x & [{:keys [as aliased] :as opts}]]
|
||||
(cond (map? x)
|
||||
(format-dsl x {:nested true})
|
||||
|
||||
(sequential? x)
|
||||
(let [s (first x)
|
||||
pair? (< 1 (count x))
|
||||
a (second x)
|
||||
pair? (= 2 (count x))
|
||||
big? (and (ident? s) (or (= "*" (name s)) (str/ends-with? (name s) ".*"))
|
||||
(ident? a) (#{"except" "replace"} (name a)))
|
||||
more? (and (< 2 (count x)) (not big?))
|
||||
[sql & params] (if (map? s)
|
||||
(format-dsl s {:nested true})
|
||||
(format-expr s))
|
||||
[sql' & params'] (when pair?
|
||||
(if (sequential? a)
|
||||
(let [[sql params] (format-expr-list a {:aliased true})]
|
||||
(into [(str/join " " sql)] params))
|
||||
(format-selectable-dsl a {:aliased true})))]
|
||||
(-> [(cond-> sql
|
||||
pair?
|
||||
(str (if as
|
||||
(if (and (contains? *dialect* :as)
|
||||
(not (:as *dialect*)))
|
||||
" "
|
||||
" AS ")
|
||||
" ") sql'))]
|
||||
[sql' & params'] (when (or pair? big?)
|
||||
(cond (sequential? a)
|
||||
(let [[sqls params] (format-expr-list a {:aliased true})]
|
||||
(into [(str/join " " sqls)] params))
|
||||
big? ; BigQuery support #281
|
||||
(reduce (fn [[sql & params] [k arg]]
|
||||
(let [[sql' params']
|
||||
(cond (and (ident? k) (= "except" (name k)) arg)
|
||||
(let [[sqls params]
|
||||
(format-expr-list arg {:aliased true})]
|
||||
[(str (sql-kw k) " (" (str/join ", " sqls) ")")
|
||||
params])
|
||||
(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')))
|
||||
|
||||
|
|
@ -376,9 +409,9 @@
|
|||
(when (empty? xs)
|
||||
(throw (ex-info (str prefix " empty column list is illegal")
|
||||
{: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})]
|
||||
(into [(str prefix " " sql)] params))))
|
||||
(into [(str (when prefix (str prefix " ")) sql)] params))))
|
||||
|
||||
(defn- format-selects [k xs]
|
||||
(format-selects-common
|
||||
|
|
@ -807,9 +840,16 @@
|
|||
(let [[if-exists tables & more] (destructure-drop-items params "DROP options")]
|
||||
[(str/join " " (remove nil? (into [(sql-kw k) if-exists tables] more)))]))
|
||||
|
||||
(def ^:private ^:dynamic *formatted-column* (atom false))
|
||||
|
||||
(defn- format-single-column [xs]
|
||||
(str/join " " (let [[id & spec] (map #(format-simple-expr % "column operation") xs)]
|
||||
(cons id (map upper-case spec)))))
|
||||
(reset! *formatted-column* true)
|
||||
(str/join " " (cons (format-simple-expr (first xs) "column operation")
|
||||
(map #(binding [*formatted-column* (atom false)]
|
||||
(cond-> (format-simple-expr % "column operation")
|
||||
(not @*formatted-column*)
|
||||
(upper-case)))
|
||||
(rest xs)))))
|
||||
|
||||
(defn- format-table-columns [_ xs]
|
||||
[(str "("
|
||||
|
|
@ -1106,6 +1146,15 @@
|
|||
;; used in DDL to force rendering as a SQL entity instead
|
||||
;; of a SQL keyword:
|
||||
:entity (fn [_ [e]] [(format-entity e)])
|
||||
;; bigquery column types:
|
||||
:bigquery/array (fn [_ spec]
|
||||
[(str "ARRAY<"
|
||||
(str/join " " (map #(format-simple-expr % "column operation") spec))
|
||||
">")])
|
||||
:bigquery/struct (fn [_ spec]
|
||||
[(str "STRUCT<"
|
||||
(str/join ", " (map format-single-column spec))
|
||||
">")])
|
||||
:array
|
||||
(fn [_ [arr]]
|
||||
(let [[sqls params] (format-expr-list arr)]
|
||||
|
|
@ -1435,6 +1484,24 @@
|
|||
(when ignore-nil
|
||||
(swap! op-ignore-nil conj op))))
|
||||
|
||||
;; helper functions to create HoneySQL data structures from other things
|
||||
|
||||
(defn map=
|
||||
"Given a hash map, return a condition structure that can be used in a
|
||||
WHERE clause to test for equality:
|
||||
|
||||
{:select :* :from :table :where (sql/map= {:id 1})}
|
||||
|
||||
will produce: SELECT * FROM table WHERE id = ? (and a parameter of 1)"
|
||||
[data]
|
||||
(let [clauses (reduce-kv (fn [where col val]
|
||||
(conj where [:= col val]))
|
||||
[]
|
||||
data)]
|
||||
(if (= 1 (count clauses))
|
||||
(first clauses)
|
||||
(into [:and] clauses))))
|
||||
|
||||
;; aids to migration from HoneySQL 1.x -- these are deliberately undocumented
|
||||
;; so as not to encourage their use for folks starting fresh with 2.x!
|
||||
|
||||
|
|
|
|||
44
test/honey/bigquery_test.cljc
Normal file
44
test/honey/bigquery_test.cljc
Normal file
|
|
@ -0,0 +1,44 @@
|
|||
;; copyright (c) 2022 sean corfield, all rights reserved
|
||||
|
||||
(ns honey.bigquery-test
|
||||
(:refer-clojure :exclude [format])
|
||||
(:require [clojure.test :refer [deftest is]]
|
||||
[honey.sql :as sut])
|
||||
#?(:clj (:import (clojure.lang ExceptionInfo))))
|
||||
|
||||
(deftest except-replace-tests
|
||||
(is (= ["SELECT * FROM table WHERE id = ?" 1]
|
||||
(sut/format {:select [:*] :from [:table] :where [:= :id 1]})))
|
||||
(is (= ["SELECT * EXCEPT (a, b, c) FROM table WHERE id = ?" 1]
|
||||
(sut/format {:select [[:* :except [:a :b :c]]] :from [:table] :where [:= :id 1]})))
|
||||
(is (= ["SELECT table.* EXCEPT (a, b, c) FROM table WHERE id = ?" 1]
|
||||
(sut/format {:select [[:table.* :except [:a :b :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]})))
|
||||
(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]})))
|
||||
(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]]}))))
|
||||
|
||||
(deftest struct-array-tests
|
||||
(is (= ["CREATE TABLE IF NOT EXISTS my_table (name STRING NOT NULL, my_struct STRUCT<name STRING NOT NULL, description STRING>, my_array ARRAY<STRING>)"]
|
||||
(sut/format (-> {:create-table [:my-table :if-not-exists]
|
||||
:with-columns
|
||||
[[:name :string [:not nil]]
|
||||
[:my_struct [:bigquery/struct [:name :string [:not nil]] [:description :string]]]
|
||||
[:my_array [:bigquery/array :string]]]}))))
|
||||
(is (= ["ALTER TABLE my_table ADD COLUMN IF NOT EXISTS name STRING, ADD COLUMN IF NOT EXISTS my_struct STRUCT<name STRING, description STRING>, ADD COLUMN IF NOT EXISTS my_array ARRAY<STRING>"]
|
||||
(sut/format {:alter-table [:my-table
|
||||
{:add-column [:name :string :if-not-exists]}
|
||||
{:add-column [:my_struct [:bigquery/struct [:name :string] [:description :string]] :if-not-exists]}
|
||||
{:add-column [:my_array [:bigquery/array :string] :if-not-exists]}]}))))
|
||||
|
|
@ -75,6 +75,8 @@
|
|||
(deftest general-tests
|
||||
(is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1]
|
||||
(sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:quoted true})))
|
||||
(is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1]
|
||||
(sut/format {:select [:*] :from [:table] :where (sut/map= {:id 1})} {:quoted true})))
|
||||
(is (= ["SELECT \"t\".* FROM \"table\" AS \"t\" WHERE \"id\" = ?" 1]
|
||||
(sut/format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {:quoted true})))
|
||||
(is (= ["SELECT * FROM \"table\" GROUP BY \"foo\", \"bar\""]
|
||||
|
|
|
|||
Loading…
Reference in a new issue