Addresses #293 by expanding insert-into behavior
This adds alias support into `:insert-into`. It also adds some tests for the PostgreSQL-specific stuff currently in nilenso's library.
This commit is contained in:
parent
0a83601c3c
commit
5318c184e6
4 changed files with 179 additions and 27 deletions
|
|
@ -99,16 +99,24 @@ or `SELECT .. BULK COLLECT INTO ..`.
|
||||||
|
|
||||||
## insert-into
|
## insert-into
|
||||||
|
|
||||||
There are two use cases with `:insert-into`. The first case
|
There are three use cases with `:insert-into`.
|
||||||
takes just a simple SQL entity (the table name). The more
|
|
||||||
complex case takes a pair of a SQL entity and a SQL query.
|
|
||||||
In that second case, you can specify the columns by using
|
|
||||||
a pair of the table name and a sequence of column names.
|
|
||||||
|
|
||||||
For the first case, you'll use the `:values` clause and you
|
The first case takes just a table specifier (either a
|
||||||
may use the `:columns` clause as well.
|
table name or a table/alias pair),
|
||||||
|
and then you can optionally specify the columns (via a `:columns` clause).
|
||||||
|
|
||||||
|
The second case takes a pair of a table specifier (either a
|
||||||
|
table name or table/alias pair) and a sequence of column
|
||||||
|
names (so you do not need to also use `:columns`).
|
||||||
|
|
||||||
|
The third case takes a pair of either a table specifier
|
||||||
|
or a table/column specifier and a SQL query.
|
||||||
|
|
||||||
|
For the first and second cases, you'll use the `:values` clause
|
||||||
|
to specify rows of values to insert.
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
|
;; first case -- table specifier:
|
||||||
user=> (sql/format {:insert-into :transport
|
user=> (sql/format {:insert-into :transport
|
||||||
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
|
|
@ -116,15 +124,37 @@ user=> (sql/format {:insert-into :transport
|
||||||
:columns [:id :name]
|
:columns [:id :name]
|
||||||
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
```
|
;; with an alias:
|
||||||
|
user=> (sql/format {:insert-into [:transport :t]
|
||||||
The second case:
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
```clojure
|
user=> (sql/format {:insert-into [:transport :t]
|
||||||
|
:columns [:id :name]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
|
;; second case -- table specifier and columns:
|
||||||
|
user=> (sql/format {:insert-into [:transport [:id :name]]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
|
;; with an alias:
|
||||||
|
user=> (sql/format {:insert-into [[:transport :t] [:id :name]]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
|
||||||
|
;; third case -- table/column specifier and query:
|
||||||
user=> (sql/format '{insert-into (transport {select (id, name) from (cars)})})
|
user=> (sql/format '{insert-into (transport {select (id, name) from (cars)})})
|
||||||
["INSERT INTO transport SELECT id, name FROM cars"]
|
["INSERT INTO transport SELECT id, name FROM cars"]
|
||||||
|
;; with columns:
|
||||||
user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
|
user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
|
||||||
["INSERT INTO transport (id, name) SELECT * FROM cars"]
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]
|
||||||
|
;; with an alias:
|
||||||
|
user=> (sql/format '{insert-into ((transport t) {select (id, name) from (cars)})})
|
||||||
|
["INSERT INTO transport AS t SELECT id, name FROM cars"]
|
||||||
|
;; with columns:
|
||||||
|
user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
|
||||||
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]
|
||||||
|
;; with an alias and columns:
|
||||||
|
user=> (sql/format '{insert-into (((transport t) (id, name)) {select (*) from (cars)})})
|
||||||
|
["INSERT INTO transport AS t (id, name) SELECT * FROM cars"]
|
||||||
```
|
```
|
||||||
|
|
||||||
## update
|
## update
|
||||||
|
|
|
||||||
|
|
@ -299,21 +299,27 @@
|
||||||
|
|
||||||
(defn- format-insert [k table]
|
(defn- format-insert [k table]
|
||||||
(if (sequential? table)
|
(if (sequential? table)
|
||||||
(cond (sequential? (first table))
|
(cond (map? (second table))
|
||||||
(let [[[table cols] statement] table
|
(let [[table statement] table
|
||||||
|
[table cols]
|
||||||
|
(if (and (sequential? table) (sequential? (second table)))
|
||||||
|
table
|
||||||
|
[table])
|
||||||
[sql & params] (format-dsl statement)]
|
[sql & params] (format-dsl statement)]
|
||||||
(into [(str (sql-kw k) " " (format-entity-alias table)
|
(into [(str (sql-kw k) " " (format-entity-alias table)
|
||||||
" ("
|
" "
|
||||||
(str/join ", " (map #'format-entity-alias cols))
|
(when (seq cols)
|
||||||
") "
|
(str "("
|
||||||
|
(str/join ", " (map #'format-entity-alias cols))
|
||||||
|
") "))
|
||||||
sql)]
|
sql)]
|
||||||
params))
|
params))
|
||||||
(map? (second table))
|
(sequential? (second table))
|
||||||
(let [[table statement] table
|
(let [[table cols] table]
|
||||||
[sql & params] (format-dsl statement)]
|
[(str (sql-kw k) " " (format-entity-alias table)
|
||||||
(into [(str (sql-kw k) " " (format-entity-alias table)
|
" ("
|
||||||
" " sql)]
|
(str/join ", " (map #'format-entity-alias cols))
|
||||||
params))
|
")")])
|
||||||
:else
|
:else
|
||||||
[(str (sql-kw k) " " (format-entity-alias table))])
|
[(str (sql-kw k) " " (format-entity-alias table))])
|
||||||
[(str (sql-kw k) " " (format-entity-alias table))]))
|
[(str (sql-kw k) " " (format-entity-alias table))]))
|
||||||
|
|
|
||||||
|
|
@ -80,10 +80,10 @@
|
||||||
(defn offset [& args] (generic-1 :offset args))
|
(defn offset [& args] (generic-1 :offset args))
|
||||||
(defn for [& args] (generic-1 :for args))
|
(defn for [& args] (generic-1 :for args))
|
||||||
(defn values [& args] (generic-1 :values args))
|
(defn values [& args] (generic-1 :values args))
|
||||||
(defn on-conflict [& args] (generic :on-conflict args))
|
(defn on-conflict [& args] (generic-1 :on-conflict args))
|
||||||
(defn on-constraint [& args] (generic :on-constraint args))
|
(defn on-constraint [& args] (generic :on-constraint args))
|
||||||
(defn do-nothing [& args] (generic :do-nothing args))
|
(defn do-nothing [& args] (generic :do-nothing args))
|
||||||
(defn do-update-set [& args] (generic :do-update-set args))
|
(defn do-update-set [& args] (generic-1 :do-update-set args))
|
||||||
(defn returning [& args] (generic :returning args))
|
(defn returning [& args] (generic :returning args))
|
||||||
|
|
||||||
;; helpers that produce non-clause expressions -- must be listed below:
|
;; helpers that produce non-clause expressions -- must be listed below:
|
||||||
|
|
|
||||||
|
|
@ -6,8 +6,10 @@
|
||||||
:cljs [cljs.test :refer-macros [deftest is testing]])
|
:cljs [cljs.test :refer-macros [deftest is testing]])
|
||||||
[honey.sql :as sql]
|
[honey.sql :as sql]
|
||||||
[honey.sql.helpers
|
[honey.sql.helpers
|
||||||
:refer [columns cross-join from full-join group-by having insert-into
|
:refer [columns cross-join do-update-set from full-join
|
||||||
join left-join limit offset order-by right-join
|
group-by having insert-into
|
||||||
|
join left-join limit offset on-conflict order-by
|
||||||
|
returning right-join
|
||||||
select select-distinct values where with]]))
|
select select-distinct values where with]]))
|
||||||
|
|
||||||
(deftest test-select
|
(deftest test-select
|
||||||
|
|
@ -274,3 +276,117 @@
|
||||||
" AND (location NOT LIKE '/0/%')"
|
" AND (location NOT LIKE '/0/%')"
|
||||||
" AND (location NOT LIKE '/1/%')")]
|
" AND (location NOT LIKE '/1/%')")]
|
||||||
(stack-overflow-282 2))))
|
(stack-overflow-282 2))))
|
||||||
|
|
||||||
|
(deftest issue-293
|
||||||
|
;; these tests are based on the README at https://github.com/nilenso/honeysql-postgres
|
||||||
|
(is (= (-> (insert-into :distributors)
|
||||||
|
(values [{:did 5 :dname "Gizmo Transglobal"}
|
||||||
|
{:did 6 :dname "Associated Computing, Inc"}])
|
||||||
|
(-> (on-conflict :did)
|
||||||
|
(do-update-set :dname))
|
||||||
|
(returning :*)
|
||||||
|
sql/format)
|
||||||
|
[(str "INSERT INTO distributors (did, dname)"
|
||||||
|
" VALUES (?, ?), (?, ?)"
|
||||||
|
" ON CONFLICT (did)"
|
||||||
|
" DO UPDATE SET dname = EXCLUDED.dname"
|
||||||
|
" RETURNING *")
|
||||||
|
5 "Gizmo Transglobal"
|
||||||
|
6 "Associated Computing, Inc"]))
|
||||||
|
(is (= (-> (insert-into :distributors)
|
||||||
|
(values [{:did 23 :dname "Foo Distributors"}])
|
||||||
|
(on-conflict :did)
|
||||||
|
;; instead of do-update-set!
|
||||||
|
(do-update-set {:dname [:|| :EXCLUDED.dname " (formerly " :distributors.dname ")"]
|
||||||
|
:downer :EXCLUDED.downer})
|
||||||
|
sql/format)
|
||||||
|
[(str "INSERT INTO distributors (did, dname)"
|
||||||
|
" VALUES (?, ?)"
|
||||||
|
" ON CONFLICT (did)"
|
||||||
|
" DO UPDATE SET dname = EXCLUDED.dname || ? || distributors.dname || ?,"
|
||||||
|
" downer = EXCLUDED.downer")
|
||||||
|
23 "Foo Distributors" " (formerly " ")"])))
|
||||||
|
|
||||||
|
(deftest issue-293-insert-into-data
|
||||||
|
;; insert into as (and other tests) based on :insert-into
|
||||||
|
;; examples in the clause reference docs:
|
||||||
|
;; first case -- table specifier:
|
||||||
|
(is (= (sql/format {:insert-into :transport
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
(is (= (sql/format {:insert-into :transport
|
||||||
|
:columns [:id :name]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format {:insert-into [:transport :t]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
(is (= (sql/format {:insert-into [:transport :t]
|
||||||
|
:columns [:id :name]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; second case -- table specifier and columns:
|
||||||
|
(is (= (sql/format {:insert-into [:transport [:id :name]]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format {:insert-into [[:transport :t] [:id :name]]
|
||||||
|
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; third case -- table/column specifier and query:
|
||||||
|
(is (= (sql/format '{insert-into (transport {select (id, name) from (cars)})})
|
||||||
|
["INSERT INTO transport SELECT id, name FROM cars"]))
|
||||||
|
;; with columns:
|
||||||
|
(is (= (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
|
||||||
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format '{insert-into ((transport t) {select (id, name) from (cars)})})
|
||||||
|
["INSERT INTO transport AS t SELECT id, name FROM cars"]))
|
||||||
|
;; with columns:
|
||||||
|
(is (= (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
|
||||||
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]))
|
||||||
|
;; with an alias and columns:
|
||||||
|
(is (= (sql/format '{insert-into (((transport t) (id, name)) {select (*) from (cars)})})
|
||||||
|
["INSERT INTO transport AS t (id, name) SELECT * FROM cars"])))
|
||||||
|
|
||||||
|
(deftest issue-293-insert-into-helpers
|
||||||
|
;; and the same set of tests using the helper functions instead:
|
||||||
|
(is (= (sql/format (-> (insert-into :transport)
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
(is (= (sql/format (-> (insert-into :transport)
|
||||||
|
(columns :id :name)
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format (-> (insert-into :transport :t)
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
(is (= (sql/format (-> (insert-into :transport :t)
|
||||||
|
(columns :id :name)
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; second case -- table specifier and columns:
|
||||||
|
(is (= (sql/format (-> (insert-into :transport [:id :name])
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format (-> (insert-into [:transport :t] [:id :name])
|
||||||
|
(values [[1 "Car"] [2 "Boat"] [3 "Bike"]])))
|
||||||
|
["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]))
|
||||||
|
;; third case -- table/column specifier and query:
|
||||||
|
(is (= (sql/format (insert-into :transport '{select (id, name) from (cars)}))
|
||||||
|
["INSERT INTO transport SELECT id, name FROM cars"]))
|
||||||
|
;; with columns:
|
||||||
|
(is (= (sql/format (insert-into [:transport [:id :name]] '{select (*) from (cars)}))
|
||||||
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]))
|
||||||
|
;; with an alias:
|
||||||
|
(is (= (sql/format (insert-into '(transport t) '{select (id, name) from (cars)}))
|
||||||
|
["INSERT INTO transport AS t SELECT id, name FROM cars"]))
|
||||||
|
;; with columns:
|
||||||
|
(is (= (sql/format (insert-into '(transport (id, name)) '{select (*) from (cars)}))
|
||||||
|
["INSERT INTO transport (id, name) SELECT * FROM cars"]))
|
||||||
|
;; with an alias and columns:
|
||||||
|
(is (= (sql/format (insert-into ['(transport t) '(id, name)] '{select (*) from (cars)}))
|
||||||
|
["INSERT INTO transport AS t (id, name) SELECT * FROM cars"])))
|
||||||
|
|
|
||||||
Loading…
Reference in a new issue