feat: insert-multi! :batch option

Adds support for using a `:batch` option to make `insert-multi!` use
`execute-batch!` instead of `execute!`.
This commit is contained in:
Ryan Schmukler 2022-05-20 12:53:23 -05:00
parent 0531ae0268
commit 003d47ea5e
3 changed files with 33 additions and 11 deletions

View file

@ -21,7 +21,7 @@
In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY` In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY`
clause to the generated SQL." clause to the generated SQL."
(:require [next.jdbc :refer [execute! execute-one!]] (:require [next.jdbc :refer [execute! execute-one! execute-batch!]]
[next.jdbc.sql.builder [next.jdbc.sql.builder
:refer [for-delete for-insert for-insert-multi :refer [for-delete for-insert for-insert-multi
for-query for-update]])) for-query for-update]]))
@ -53,8 +53,12 @@
Also supports a sequence of hash maps with keys corresponding to column Also supports a sequence of hash maps with keys corresponding to column
names. names.
Note: this expands to a single SQL statement with placeholders for every If called with `:batch` true will call `execute-batch!` - see its documentation
value being inserted -- for large sets of rows, this may exceed the limits for situations in which the generated keys may or may not be returned as well as
additional options that can be passed.
Note: without `:batch` this expands to a single SQL statement with placeholders for
every value being inserted -- for large sets of rows, this may exceed the limits
on SQL string size and/or number of parameters for your JDBC driver or your on SQL string size and/or number of parameters for your JDBC driver or your
database!" database!"
{:arglists '([connectable table hash-maps] {:arglists '([connectable table hash-maps]
@ -72,10 +76,15 @@
(insert-multi! connectable table cols (map ->row hash-maps-or-cols) opts-or-rows)))) (insert-multi! connectable table cols (map ->row hash-maps-or-cols) opts-or-rows))))
([connectable table cols rows opts] ([connectable table cols rows opts]
(if (seq rows) (if (seq rows)
(let [opts (merge (:options connectable) opts)] (let [opts (merge (:options connectable) opts)
batch? (:batch opts)]
(if batch?
(let [[sql & param-groups] (for-insert-multi table cols rows opts)]
(execute-batch! connectable sql param-groups
(merge {:return-keys true :return-generated-keys true} opts)))
(execute! connectable (execute! connectable
(for-insert-multi table cols rows opts) (for-insert-multi table cols rows opts)
(merge {:return-keys true} opts))) (merge {:return-keys true} opts))))
[]))) [])))
(defn query (defn query

View file

@ -137,6 +137,10 @@
Applies any `:table-fn` / `:column-fn` supplied in the options. Applies any `:table-fn` / `:column-fn` supplied in the options.
If `:batch` is set to `true` in `opts` the INSERT statement will be prepared
using a single set of placeholders and remaining parameters in the vector will
be grouped at the row level.
If `:suffix` is provided in `opts`, that string is appended to the If `:suffix` is provided in `opts`, that string is appended to the
`INSERT ...` statement." `INSERT ...` statement."
[table cols rows opts] [table cols rows opts]
@ -147,15 +151,16 @@
(assert (seq rows) "rows may not be empty") (assert (seq rows) "rows may not be empty")
(let [table-fn (:table-fn opts identity) (let [table-fn (:table-fn opts identity)
column-fn (:column-fn opts identity) column-fn (:column-fn opts identity)
batch? (:batch opts)
params (str/join ", " (map (comp column-fn name) cols)) params (str/join ", " (map (comp column-fn name) cols))
places (as-? (first rows) opts)] places (as-? (first rows) opts)]
(into [(str "INSERT INTO " (table-fn (safe-name table)) (into [(str "INSERT INTO " (table-fn (safe-name table))
" (" params ")" " (" params ")"
" VALUES " " VALUES "
(str/join ", " (repeat (count rows) (str "(" places ")"))) (str/join ", " (repeat (if batch? 1 (count rows)) (str "(" places ")")))
(when-let [suffix (:suffix opts)] (when-let [suffix (:suffix opts)]
(str " " suffix)))] (str " " suffix)))]
cat (if batch? identity cat)
rows))) rows)))
(defn for-order-col (defn for-order-col

View file

@ -146,11 +146,19 @@
{:id 9 :status 42 :opt nil} {:id 9 :status 42 :opt nil}
{:table-fn sql-server :column-fn mysql}) {:table-fn sql-server :column-fn mysql})
["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil]))) ["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil])))
(testing "multi-row insert" (testing "multi-row insert (normal mode)"
(is (= (builder/for-insert-multi :user (is (= (builder/for-insert-multi :user
[:id :status] [:id :status]
[[42 "hello"] [[42 "hello"]
[35 "world"] [35 "world"]
[64 "dollars"]] [64 "dollars"]]
{:table-fn sql-server :column-fn mysql}) {:table-fn sql-server :column-fn mysql})
["INSERT INTO [user] (`id`, `status`) VALUES (?, ?), (?, ?), (?, ?)" 42 "hello" 35 "world" 64 "dollars"])))) ["INSERT INTO [user] (`id`, `status`) VALUES (?, ?), (?, ?), (?, ?)" 42 "hello" 35 "world" 64 "dollars"])))
(testing "multi-row insert (batch mode)"
(is (= (builder/for-insert-multi :user
[:id :status]
[[42 "hello"]
[35 "world"]
[64 "dollars"]]
{:table-fn sql-server :column-fn mysql :batch true})
["INSERT INTO [user] (`id`, `status`) VALUES (?, ?)" [42 "hello"] [35 "world"] [64 "dollars"]]))))