fix #501 by making insert/columns/values talk to each other

This commit is contained in:
Sean Corfield 2023-08-26 16:20:32 -07:00
parent aa4ebf5f47
commit 44ffd340f5
6 changed files with 163 additions and 128 deletions

View file

@ -1,11 +1,12 @@
# Changes # Changes
* 2.4.next in progress * 2.4.next in progress
* Add `:create-or-replace-view` to support PostgreSQL's lack of `IF NOT EXISTS` for `CREATE VIEW`.
* Add `:select` with function call and alias example to README (PR [#502](https://github.com/seancorfield/honeysql/pull/502) [@markbastian](https://github.com/markbastian)). * Add `:select` with function call and alias example to README (PR [#502](https://github.com/seancorfield/honeysql/pull/502) [@markbastian](https://github.com/markbastian)).
* Address [#501](https://github.com/seancorfield/honeysql/issues/501) by making `INSERT INTO` (and `REPLACE INTO`) use the `:columns` or `:values` clauses to produce column names (which are then omitted from those other clauses).
* Address [#497](https://github.com/seancorfield/honeysql/issues/497) by adding `:alias` special syntax. * Address [#497](https://github.com/seancorfield/honeysql/issues/497) by adding `:alias` special syntax.
* Address [#407](https://github.com/seancorfield/honeysql/issues/407) by adding support for temporal queries (see `FROM` in [SQL Clause Reference](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started/sql-clause-reference#from)). * Address [#407](https://github.com/seancorfield/honeysql/issues/407) by adding support for temporal queries (see `FROM` in [SQL Clause Reference](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started/sql-clause-reference#from)).
* Address [#389](https://github.com/seancorfield/honeysql/issues/389) by adding examples of `[:only :table]` producing `ONLY(table)`. * Address [#389](https://github.com/seancorfield/honeysql/issues/389) by adding examples of `[:only :table]` producing `ONLY(table)`.
* Add `:create-or-replace-view` to support PostgreSQL's lack of `IF NOT EXISTS` for `CREATE VIEW`.
* Attempt to clarify the formatting behavior of the `:values` clause when used to produce column names. * Attempt to clarify the formatting behavior of the `:values` clause when used to produce column names.
* Update `tools.build` to 0.9.5 (and remove `:java-opts` setting from `build/run-task`) * Update `tools.build` to 0.9.5 (and remove `:java-opts` setting from `build/run-task`)

View file

@ -241,8 +241,7 @@ then provide a collection of rows, each a collection of column values:
["Jane" "Daniels" 56]]) ["Jane" "Daniels" 56]])
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age)
VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
" "
"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56]
@ -254,8 +253,7 @@ VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
["Jane" "Daniels" 56]]} ["Jane" "Daniels" 56]]}
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age)
VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
" "
"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56]
@ -272,8 +270,8 @@ Alternately, you can simply specify the values as maps:
{:name "Jane" :surname "Daniels" :age 56}]) {:name "Jane" :surname "Daniels" :age 56}])
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
" "
"John" "Smith" 34 "John" "Smith" 34
"Andrew" "Cooper" 12 "Andrew" "Cooper" 12
@ -285,8 +283,8 @@ INSERT INTO properties
{:name "Jane", :surname "Daniels", :age 56}]} {:name "Jane", :surname "Daniels", :age 56}]}
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
" "
"John" "Smith" 34 "John" "Smith" 34
"Andrew" "Cooper" 12 "Andrew" "Cooper" 12
@ -306,8 +304,8 @@ a set of column names that should get the value `DEFAULT` instead of `NULL`:
{:name "Jane" :surname "Daniels"}]) {:name "Jane" :surname "Daniels"}])
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, NULL) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, NULL)
" "
"John" "Smith" 34 "John" "Smith" 34
"Andrew" 12 "Andrew" 12
@ -318,8 +316,8 @@ INSERT INTO properties
{:name "Jane" :surname "Daniels"}]) {:name "Jane" :surname "Daniels"}])
(sql/format {:pretty true :values-default-columns #{:age}})) (sql/format {:pretty true :values-default-columns #{:age}}))
=> [" => ["
INSERT INTO properties INSERT INTO properties (name, surname, age)
(name, surname, age) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, DEFAULT) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, DEFAULT)
" "
"John" "Smith" 34 "John" "Smith" 34
"Andrew" 12 "Andrew" 12
@ -341,8 +339,8 @@ The column values do not have to be literals, they can be nested queries:
(sql/format {:pretty true}))) (sql/format {:pretty true})))
=> [" => ["
INSERT INTO user_profile_to_role INSERT INTO user_profile_to_role (user_profile_id, role_id)
(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?)) VALUES (?, (SELECT id FROM role WHERE name = ?))
" "
12345 12345
"user"] "user"]
@ -356,8 +354,8 @@ INSERT INTO user_profile_to_role
:where [:= :name "user"]}}]} :where [:= :name "user"]}}]}
(sql/format {:pretty true}))) (sql/format {:pretty true})))
=> [" => ["
INSERT INTO user_profile_to_role INSERT INTO user_profile_to_role (user_profile_id, role_id)
(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?)) VALUES (?, (SELECT id FROM role WHERE name = ?))
" "
12345 12345
"user"] "user"]
@ -398,8 +396,7 @@ Composite types are supported:
["large" (composite 10 "feet")]]) ["large" (composite 10 "feet")]])
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO comp_table INSERT INTO comp_table (name, comp_column)
(name, comp_column)
VALUES (?, (?, ?)), (?, (?, ?)) VALUES (?, (?, ?)), (?, (?, ?))
" "
"small" 1 "inch" "large" 10 "feet"] "small" 1 "inch" "large" 10 "feet"]
@ -411,8 +408,7 @@ VALUES (?, (?, ?)), (?, (?, ?))
["large" (composite 10 "feet")]]) ["large" (composite 10 "feet")]])
(sql/format {:pretty true :numbered true})) (sql/format {:pretty true :numbered true}))
=> [" => ["
INSERT INTO comp_table INSERT INTO comp_table (name, comp_column)
(name, comp_column)
VALUES ($1, ($2, $3)), ($4, ($5, $6)) VALUES ($1, ($2, $3)), ($4, ($5, $6))
" "
"small" 1 "inch" "large" 10 "feet"] "small" 1 "inch" "large" 10 "feet"]
@ -423,8 +419,7 @@ VALUES ($1, ($2, $3)), ($4, ($5, $6))
["large" [:composite 10 "feet"]]]} ["large" [:composite 10 "feet"]]]}
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO comp_table INSERT INTO comp_table (name, comp_column)
(name, comp_column)
VALUES (?, (?, ?)), (?, (?, ?)) VALUES (?, (?, ?)), (?, (?, ?))
" "
"small" 1 "inch" "large" 10 "feet"] "small" 1 "inch" "large" 10 "feet"]
@ -606,8 +601,8 @@ regular function calls in a select:
=> ["SELECT MAX(id) FROM foo"] => ["SELECT MAX(id) FROM foo"]
``` ```
Custom columns using functions are built with the same vector format. Custom columns using functions are built with the same vector format.
Be sure to properly nest the vectors so that the first element in the selection Be sure to properly nest the vectors so that the first element in the selection
is the custom function and the second is the column alias. is the custom function and the second is the column alias.
```clojure ```clojure
(sql/format (sql/format
@ -751,8 +746,8 @@ have a lot of function calls needed in code:
[:cast 4325 :integer]]}]) [:cast 4325 :integer]]}])
(sql/format {:pretty true})) (sql/format {:pretty true}))
=> [" => ["
INSERT INTO sample INSERT INTO sample (location)
(location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS INTEGER))) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS INTEGER)))
" "
0.291 32.621 4325] 0.291 32.621 4325]
``` ```

View file

@ -585,7 +585,8 @@ There are three use cases with `:insert-into`.
The first case takes just a table specifier (either a The first case takes just a table specifier (either a
table name or a table/alias pair), table name or a table/alias pair),
and then you can optionally specify the columns (via a `:columns` clause). and then you can optionally specify the columns (via a `:columns` clause,
or via a `:values` clause using hash maps).
The second case takes a pair of a table specifier (either a The second case takes a pair of a table specifier (either a
table name or table/alias pair) and a sequence of column table name or table/alias pair) and a sequence of column
@ -1103,8 +1104,12 @@ values.
### values with hash maps ### values with hash maps
If you provide a sequence of hash maps, the `:values` clause If you provide a sequence of hash maps, the `:values` clause
will generate a `VALUES` clause with the column names preceding will generate a `VALUES` clause, and will also generate the column names
and the row values following. as part of the `INSERT INTO` (or `REPLACE INTO`) statement.
If there is no `INSERT INTO` (or `REPLACE INTO`) statement in the context
of the `:values` clause, the column names will be generated as a part of
the `VALUES` clause itself.
```clojure ```clojure
user=> (sql/format {:values [{:col-a 1 :col-b 2}]}) user=> (sql/format {:values [{:col-a 1 :col-b 2}]})

View file

@ -102,8 +102,8 @@ user=> (-> (insert-into :distributors)
(returning :*) (returning :*)
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?), (?, ?) VALUES (?, ?), (?, ?)
ON CONFLICT (did) ON CONFLICT (did)
DO UPDATE SET dname = EXCLUDED.dname DO UPDATE SET dname = EXCLUDED.dname
RETURNING * RETURNING *
@ -124,8 +124,8 @@ user=> (-> (insert-into :distributors)
(returning :*) (returning :*)
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?), (?, ?) VALUES (?, ?), (?, ?)
ON CONFLICT (did) ON CONFLICT (did)
DO UPDATE SET dname = EXCLUDED.dname DO UPDATE SET dname = EXCLUDED.dname
RETURNING * RETURNING *
@ -144,8 +144,8 @@ user=> (-> (insert-into :distributors)
do-nothing)) do-nothing))
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (did) ON CONFLICT (did)
DO NOTHING DO NOTHING
" "
@ -161,8 +161,8 @@ user=> (-> (insert-into :distributors)
do-nothing do-nothing
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (did) ON CONFLICT (did)
DO NOTHING DO NOTHING
" "
@ -180,8 +180,8 @@ user=> (-> (insert-into :distributors)
do-nothing do-nothing
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT ON CONSTRAINT distributors_pkey ON CONFLICT ON CONSTRAINT distributors_pkey
DO NOTHING DO NOTHING
" "
@ -194,8 +194,8 @@ user=> (-> (insert-into :distributors)
do-nothing do-nothing
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO distributors INSERT INTO distributors (did, dname)
(did, dname) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT ON CONFLICT
ON CONSTRAINT distributors_pkey ON CONSTRAINT distributors_pkey
DO NOTHING DO NOTHING
@ -215,8 +215,8 @@ user=> (-> (insert-into :user)
(do-update-set :phone :name (where [:= :user.active false])) (do-update-set :phone :name (where [:= :user.active false]))
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO user INSERT INTO user (phone, name)
(phone, name) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (phone) WHERE phone IS NOT NULL ON CONFLICT (phone) WHERE phone IS NOT NULL
DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE
" "
@ -231,8 +231,8 @@ user=> (sql/format
:where [:= :user.active false]}} :where [:= :user.active false]}}
{:pretty true}) {:pretty true})
[" ["
INSERT INTO user INSERT INTO user (phone, name)
(phone, name) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (phone) WHERE phone IS NOT NULL ON CONFLICT (phone) WHERE phone IS NOT NULL
DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE
" "
@ -268,8 +268,8 @@ user=> (-> (insert-into :table)
(do-update-set {:counter [:+ :table.counter 1]}) (do-update-set {:counter [:+ :table.counter 1]})
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO table INSERT INTO table (id, counter)
(id, counter) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (id) ON CONFLICT (id)
DO UPDATE SET counter = table.counter + ? DO UPDATE SET counter = table.counter + ?
" "id" 1 1] " "id" 1 1]
@ -280,8 +280,8 @@ user=> (-> {:insert-into :table
:do-update-set {:counter [:+ :table.counter 1]}} :do-update-set {:counter [:+ :table.counter 1]}}
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO table INSERT INTO table (id, counter)
(id, counter) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (id) ON CONFLICT (id)
DO UPDATE SET counter = table.counter + ? DO UPDATE SET counter = table.counter + ?
" "id" 1 1] " "id" 1 1]
@ -300,8 +300,8 @@ user=> (-> (insert-into :table)
:where [:> :table.counter 1]}) :where [:> :table.counter 1]})
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO table INSERT INTO table (id, counter)
(id, counter) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (id) ON CONFLICT (id)
DO UPDATE SET counter = table.counter + ? WHERE table.counter > ? DO UPDATE SET counter = table.counter + ? WHERE table.counter > ?
" "id" 1 1 1] " "id" 1 1 1]
@ -313,8 +313,8 @@ user=> (-> {:insert-into :table
:where [:> :table.counter 1]}} :where [:> :table.counter 1]}}
(sql/format {:pretty true})) (sql/format {:pretty true}))
[" ["
INSERT INTO table INSERT INTO table (id, counter)
(id, counter) VALUES (?, ?) VALUES (?, ?)
ON CONFLICT (id) ON CONFLICT (id)
DO UPDATE SET counter = table.counter + ? WHERE table.counter > ? DO UPDATE SET counter = table.counter + ? WHERE table.counter > ?
" "id" 1 1 1] " "id" 1 1 1]

View file

@ -132,7 +132,7 @@
(def ^:private ^:dynamic *allow-suspicious-entities* false) (def ^:private ^:dynamic *allow-suspicious-entities* false)
;; "linting" mode (:none, :basic, :strict): ;; "linting" mode (:none, :basic, :strict):
(def ^:private ^:dynamic *checking* @default-checking) (def ^:private ^:dynamic *checking* @default-checking)
;; the current DSL hash map being formatted (for contains-clause?): ;; the current DSL hash map being formatted (for clause-body / contains-clause?):
(def ^:private ^:dynamic *dsl* nil) (def ^:private ^:dynamic *dsl* nil)
;; caching data to detect expressions that cannot be cached: ;; caching data to detect expressions that cannot be cached:
(def ^:private ^:dynamic *caching* nil) (def ^:private ^:dynamic *caching* nil)
@ -140,15 +140,21 @@
;; clause helpers ;; clause helpers
(defn clause-body
"If the current DSL expression being formatted contains the specified clause
(as a keyword or symbol), returns that clause's value."
[clause]
(or (get *dsl* clause)
(get *dsl*
(if (keyword? clause)
(symbol (name clause))
(keyword (name clause))))))
(defn contains-clause? (defn contains-clause?
"Returns true if the current DSL expression being formatted "Returns true if the current DSL expression being formatted
contains the specified clause (as a keyword or symbol)." contains the specified clause (as a keyword or symbol)."
[clause] [clause]
(or (contains? *dsl* clause) (some? (clause-body clause)))
(contains? *dsl*
(if (keyword? clause)
(symbol (name clause))
(keyword (name clause))))))
(defn- mysql? (defn- mysql?
"Helper to detect if MySQL is the current dialect." "Helper to detect if MySQL is the current dialect."
@ -628,8 +634,12 @@
) )
(defn- format-columns [k xs] (defn- format-columns [k xs]
(let [[sqls params] (format-expr-list xs {:drop-ns (= :columns k)})] (if (and (= :columns k)
(into [(str "(" (str/join ", " sqls) ")")] params))) (or (contains-clause? :insert-into)
(contains-clause? :replace-into)))
[]
(let [[sqls params] (format-expr-list xs {:drop-ns true})]
(into [(str "(" (str/join ", " sqls) ")")] params))))
(defn- format-selects-common [prefix as xs] (defn- format-selects-common [prefix as xs]
(if (sequential? xs) (if (sequential? xs)
@ -732,42 +742,60 @@
(defn- format-selector [k xs] (defn- format-selector [k xs]
(format-selects k [xs])) (format-selects k [xs]))
(declare columns-from-values)
(defn- format-insert [k table] (defn- format-insert [k table]
(if (sequential? table) (let [[cols' cols-sql' cols-params']
(cond (map? (second table)) (if-let [columns (clause-body :columns)]
(let [[table statement] table (cons columns (format-columns :force-columns columns))
[table cols] (when-let [values (clause-body :values)]
(if (and (sequential? table) (sequential? (second table))) (columns-from-values values false)))]
table (if (sequential? table)
[table]) (cond (map? (second table))
[sql & params] (format-dsl statement) (let [[table statement] table
[t-sql & t-params] (format-entity-alias table) [table cols]
[c-sqls c-params] (reduce-sql (map #'format-entity-alias cols))] (if (and (sequential? table) (sequential? (second table)))
(-> [(str (sql-kw k) " " t-sql table
" " [table])
(when (seq cols) [sql & params] (format-dsl statement)
(str "(" [t-sql & t-params] (format-entity-alias table)
(str/join ", " c-sqls) [c-sqls c-params] (reduce-sql (map #'format-entity-alias cols))]
") ")) (-> [(str (sql-kw k) " " t-sql
sql)] " "
(into t-params) (cond (seq cols)
(into c-params) (str "("
(into params))) (str/join ", " c-sqls)
(sequential? (second table)) ") ")
(let [[table cols] table (seq cols')
[t-sql & t-params] (format-entity-alias table) (str cols-sql' " "))
[c-sqls c-params] (reduce-sql (map #'format-entity-alias cols))] sql)]
(-> [(str (sql-kw k) " " t-sql (into t-params)
" (" (into c-params)
(str/join ", " c-sqls) (into cols-params')
")")] (into params)))
(into t-params) (sequential? (second table))
(into c-params))) (let [[table cols] table
:else [t-sql & t-params] (format-entity-alias table)
(let [[sql & params] (format-entity-alias table)] [c-sqls c-params] (reduce-sql (map #'format-entity-alias cols))]
(into [(str (sql-kw k) " " sql)] params))) (-> [(str (sql-kw k) " " t-sql
(let [[sql & params] (format-entity-alias table)] " ("
(into [(str (sql-kw k) " " sql)] params)))) (str/join ", " c-sqls)
")")]
(into t-params)
(into c-params)))
:else
(let [[sql & params] (format-entity-alias table)]
(-> [(str (sql-kw k) " " sql
(when (seq cols')
(str " " cols-sql')))]
(into cols-params')
(into params))))
(let [[sql & params] (format-entity-alias table)]
(-> [(str (sql-kw k) " " sql
(when (seq cols')
(str " " cols-sql')))]
(into cols-params')
(into params))))))
(comment (comment
(format-insert :insert-into [[[:raw ":foo"]] {:select :bar}]) (format-insert :insert-into [[[:raw ":foo"]] {:select :bar}])
@ -879,6 +907,22 @@
(when nowait (when nowait
(str " " (sql-kw nowait))))))])) (str " " (sql-kw nowait))))))]))
(defn- columns-from-values [xs skip-cols-sql]
(let [first-xs (when (sequential? xs) (first (drop-while ident? xs)))]
(when (map? first-xs)
(let [cols-1 (keys (first xs))
;; issue #291: check for all keys in all maps but still
;; use the keys from the first map if they match so that
;; users can rely on the key ordering if they want to,
;; e.g., see test that uses array-map for the first row
cols-n (into #{} (mapcat keys) (filter map? xs))
cols (if (= (set cols-1) cols-n) cols-1 cols-n)]
[cols (when-not skip-cols-sql
(str "("
(str/join ", "
(map #(format-entity % {:drop-ns true}) cols))
")"))]))))
(defn- format-values [k xs] (defn- format-values [k xs]
(let [first-xs (when (sequential? xs) (first (drop-while ident? xs)))] (let [first-xs (when (sequential? xs) (first (drop-while ident? xs)))]
(cond (contains? #{:default 'default} xs) (cond (contains? #{:default 'default} xs)
@ -913,13 +957,10 @@
(map? first-xs) (map? first-xs)
;; [{:a 1 :b 2 :c 3}] ;; [{:a 1 :b 2 :c 3}]
(let [cols-1 (keys (first xs)) (let [[cols cols-sql]
;; issue #291: check for all keys in all maps but still (columns-from-values xs (or (contains-clause? :insert-into)
;; use the keys from the first map if they match so that (contains-clause? :replace-into)
;; users can rely on the key ordering if they want to, (contains-clause? :columns)))
;; e.g., see test that uses array-map for the first row
cols-n (into #{} (mapcat keys) (filter map? xs))
cols (if (= (set cols-1) cols-n) cols-1 cols-n)
[sqls params] [sqls params]
(reduce (fn [[sql params] [sqls' params']] (reduce (fn [[sql params] [sqls' params']]
[(conj sql [(conj sql
@ -941,10 +982,8 @@
cols)) cols))
[(sql-kw m)])) [(sql-kw m)]))
xs))] xs))]
(into [(str "(" (into [(str (when cols-sql
(str/join ", " (str cols-sql " "))
(map #(format-entity % {:drop-ns true}) cols))
") "
(sql-kw k) (sql-kw k)
" " " "
(str/join ", " sqls))] (str/join ", " sqls))]
@ -2187,10 +2226,6 @@
:where [:= :u.id :u2.id]} :where [:= :u.id :u2.id]}
{:inline true}) {:inline true})
(sql/register-clause! :output :select :values)
(sql/format {:insert-into :foo :output [:inserted.*] :values [{:bar 1}]})
(sql/format {:insert-into :foo :columns [:bar] :output [:inserted.*] :values [[1]]})
(sql/format {:select [[:a.b :c.d]]} {:dialect :mysql}) (sql/format {:select [[:a.b :c.d]]} {:dialect :mysql})
(sql/format {:select [[:column-name :'some-alias]] (sql/format {:select [[:column-name :'some-alias]]
:from :b :from :b

View file

@ -687,8 +687,7 @@ VALUES (?, ?, ?, ?, ?, ?)
:values [["UA502" "Bananas" 105 "1971-07-13" "Comedy" "82 minutes"]]} :values [["UA502" "Bananas" 105 "1971-07-13" "Comedy" "82 minutes"]]}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO films INSERT INTO films (code, title, did, date_prod, kind)
(code, title, did, date_prod, kind)
VALUES (?, ?, ?, ?, ?) VALUES (?, ?, ?, ?, ?)
" "T_601", "Yojimo", 106, "1961-06-16", "Drama"] " "T_601", "Yojimo", 106, "1961-06-16", "Drama"]
(format {:insert-into :films (format {:insert-into :films
@ -703,8 +702,7 @@ VALUES (?, ?, ?, DEFAULT, ?, ?)
:values [["UA502" "Bananas" 105 [:default] "Comedy" "82 minutes"]]} :values [["UA502" "Bananas" 105 [:default] "Comedy" "82 minutes"]]}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO films INSERT INTO films (code, title, did, date_prod, kind)
(code, title, did, date_prod, kind)
VALUES (?, ?, ?, DEFAULT, ?) VALUES (?, ?, ?, DEFAULT, ?)
" "T_601", "Yojimo", 106, "Drama"] " "T_601", "Yojimo", 106, "Drama"]
(format {:insert-into :films (format {:insert-into :films
@ -715,8 +713,7 @@ VALUES (?, ?, ?, DEFAULT, ?)
(deftest on-conflict-tests (deftest on-conflict-tests
;; these examples are taken from https://www.postgresqltutorial.com/postgresql-upsert/ ;; these examples are taken from https://www.postgresqltutorial.com/postgresql-upsert/
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT ON CONSTRAINT customers_name_key ON CONFLICT ON CONSTRAINT customers_name_key
DO NOTHING DO NOTHING
@ -728,8 +725,7 @@ DO NOTHING
:do-nothing true} :do-nothing true}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT ON CONFLICT
ON CONSTRAINT customers_name_key ON CONSTRAINT customers_name_key
@ -743,8 +739,7 @@ DO NOTHING
:do-nothing true} :do-nothing true}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT (name) ON CONFLICT (name)
DO NOTHING DO NOTHING
@ -756,8 +751,7 @@ DO NOTHING
:do-nothing true} :do-nothing true}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT (name) ON CONFLICT (name)
DO NOTHING DO NOTHING
@ -769,8 +763,7 @@ DO NOTHING
:do-nothing true} :do-nothing true}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT ((foo + ?), name, (TRIM(email))) ON CONFLICT ((foo + ?), name, (TRIM(email)))
DO NOTHING DO NOTHING
@ -782,8 +775,7 @@ DO NOTHING
:do-nothing true} :do-nothing true}
{:pretty true}))) {:pretty true})))
(is (= [" (is (= ["
INSERT INTO customers INSERT INTO customers (name, email)
(name, email)
VALUES ('Microsoft', 'hotline@microsoft.com') VALUES ('Microsoft', 'hotline@microsoft.com')
ON CONFLICT (name) ON CONFLICT (name)
DO UPDATE SET email = EXCLUDED.email || ';' || customers.email DO UPDATE SET email = EXCLUDED.email || ';' || customers.email
@ -1250,6 +1242,13 @@ ORDER BY id = ? DESC
:order-by [[[:alias "some-alias"]]]} :order-by [[[:alias "some-alias"]]]}
{:dialect :mysql})))) {:dialect :mysql}))))
(deftest output-clause-post-501
(sut/register-clause! :output :select :values)
(is (= ["INSERT INTO foo (bar) OUTPUT inserted.* VALUES (?)" 1]
(sut/format {:insert-into :foo :output [:inserted.*] :values [{:bar 1}]})))
(is (= ["INSERT INTO foo (bar) OUTPUT inserted.* VALUES (?)" 1]
(sut/format {:insert-into :foo :columns [:bar] :output [:inserted.*] :values [[1]]}))))
(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]})