Fixes #161 by adding batch execution for connectable/SQL

This commit is contained in:
Sean Corfield 2021-03-15 15:16:59 -07:00
parent 21ca944b24
commit 7e13e719ce
6 changed files with 149 additions and 7 deletions

View file

@ -2,6 +2,9 @@
Only accretive/fixative changes will be made from now on.
* 1.1.next in progress
* Fix #161 by allowing `execute-batch!` to work with datasources and connections, and providing the SQL statement directly.
## Stable Builds
* 1.1.643 -- 2021-03-06

View file

@ -87,7 +87,7 @@ Not all databases or drivers support all of these options, or all values for any
> Note: If `plan`, `execute!`, or `execute-one!` are passed a `DataSource`, a "db spec" hash map, or a JDBC URL string, they will call `prepare` to create a `PreparedStatement`, so they will accept the above options in those cases.
In addition to the above, `next.jdbc/execute-batch!` (which does **not** create a `PreparedStatement`) accepts an options hash map that can also contain the following:
In addition to the above, `next.jdbc/execute-batch!` (which may create a `PreparedStatement` if you pass in a SQL string and either a `Connection` or `DataSource`) accepts an options hash map that can also contain the following:
* `:batch-size` -- an integer that determines how to partition the parameter groups for submitting to the database in batches,
* `:large` -- a Boolean flag that indicates whether the batch will produce large update counts (`long` rather than `int` values),

View file

@ -99,6 +99,13 @@ Both of those are somewhat ugly and contain a fair bit of boilerplate and Java i
(with-open [con (jdbc/get-connection ds)
ps (jdbc/prepare con ["insert into status (id,name) values (?,?)"])]
(jdbc/execute-batch! ps [[1 "Approved"] [2 "Rejected"] [3 "New"]]))
;; or:
(jdbc/execute-batch! ds
"insert into status (id,name) values (?,?)"
[[1 "Approved"] [2 "Rejected"] [3 "New"]]
;; options hash map required here to disambiguate
;; this call from the 2- & 3-arity calls
{})
```
By default, this adds all the parameter groups and executes one batched command. It returns a (Clojure) vector of update counts (rather than `int[]`). If you provide an options hash map, you can specify a `:batch-size` and the parameter groups will be partitioned and executed as multiple batched commands. This is intended to allow very large sequences of parameter groups to be executed without running into limitations that may apply to a single batched command. If you expect the update counts to be very large (more than `Integer/MAX_VALUE`), you can specify `:large true` so that `.executeLargeBatch` is called instead of `.executeBatch`.
@ -116,6 +123,12 @@ If you want to get the generated keys from an `insert` done via `execute-batch!`
;; vector of datafiable result sets (the keys in map are database-specific):
(jdbc/execute-batch! ps [[1 "Approved"] [2 "Rejected"] [3 "New"]]
{:return-generated-keys true}))
;; or:
(jdbc/execute-batch! ds
"insert into status (id,name) values (?,?)"
[[1 "Approved"] [2 "Rejected"] [3 "New"]]
{:return-keys true ; for creation of PreparedStatement
:return-generated-keys true}) ; for batch result format
```
This calls `rs/datafiable-result-set` behind the scenes so you can also pass a `:builder-fn` option to `execute-batch!` if you want something other than qualified as-is hash maps.

View file

@ -27,7 +27,9 @@
navigation of foreign keys into other tables (either by convention or
via a schema definition),
* `execute-batch!` -- given a `PreparedStatement` and groups of parameters,
execute the statement in batch mode (via `.executeBatch`).
execute the statement in batch mode (via `.executeBatch`); given a
connectable, a SQL string, and groups of parameters, create a new
`PreparedStatement` from the SQL and execute it in batch mode.
* `prepare` -- given a `Connection` and SQL + parameters, construct a new
`PreparedStatement`; in general this should be used with `with-open`,
* `transact` -- the functional implementation of `with-transaction`,
@ -276,6 +278,12 @@
you can specify `:large true` and `.executeLargeBatch` will be called
instead.
Alternatively, given a connectable, a SQL string, a vector containing
parameter groups, and an options hash map, create a new `PreparedStatement`
(after possibly creating a new `Connection`), and execute the SQL with
the specified parameter groups. That new `PreparedStatement` (and the
new `Connection`, if created) will be closed automatically after use.
By default, returns a Clojure vector of update counts. Some databases
allow batch statements to also return generated keys and you can attempt that
if you ensure the `PreparedStatement` is created with `:return-keys true`
@ -314,7 +322,13 @@
(p/get-connection ps {})
opts)
result))))
params))))
params)))
([connectable sql param-groups opts]
(if (instance? java.sql.Connection connectable)
(with-open [ps (prepare connectable [sql] opts)]
(execute-batch! ps param-groups opts))
(with-open [con (get-connection connectable)]
(execute-batch! con sql param-groups opts)))))
(defn transact
"Given a transactable object and a function (taking a `Connection`),

View file

@ -129,9 +129,13 @@
:opts (s/? ::opts-map))))
(s/fdef jdbc/execute-batch!
:args (s/cat :ps ::prepared-statement
:param-groups (s/coll-of ::params :kind sequential?)
:opts (s/? ::batch-opts)))
:args (s/alt :prepared (s/cat :ps ::prepared-statement
:param-groups (s/coll-of ::params :kind sequential?)
:opts (s/? ::batch-opts))
:sql (s/cat :connectable ::connectable
:sql string?
:param-groups (s/coll-of ::params :kind sequential?)
:opts ::batch-opts)))
(s/fdef jdbc/transact
:args (s/cat :transactable ::transactable

View file

@ -483,7 +483,6 @@ VALUES ('Pear', 'green', 49, 47)
(is (every? boolean? (map :is_it data)))
(is (every? boolean? (map :twiddle data)))))
(deftest execute-batch-tests
(testing "simple batch insert"
(is (= [1 1 1 1 1 1 1 1 1 13]
@ -585,6 +584,115 @@ INSERT INTO fruit (name, appearance) VALUES (?,?)
(is (< 3 (count results))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"])))))))
(deftest execute-batch-connectable-tests
(testing "simple batch insert"
(is (= [1 1 1 1 1 1 1 1 1 13]
(try
(let [result (jdbc/execute-batch! (ds)
"INSERT INTO fruit (name, appearance) VALUES (?,?)"
[["fruit1" "one"]
["fruit2" "two"]
["fruit3" "three"]
["fruit4" "four"]
["fruit5" "five"]
["fruit6" "six"]
["fruit7" "seven"]
["fruit8" "eight"]
["fruit9" "nine"]]
{})]
(conj result (count (jdbc/execute! (ds) ["select * from fruit"]))))
(finally
(jdbc/execute-one! (ds) ["delete from fruit where id > 4"])))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"])))))
(testing "small batch insert"
(is (= [1 1 1 1 1 1 1 1 1 13]
(try
(let [result (jdbc/execute-batch! (ds)
"INSERT INTO fruit (name, appearance) VALUES (?,?)"
[["fruit1" "one"]
["fruit2" "two"]
["fruit3" "three"]
["fruit4" "four"]
["fruit5" "five"]
["fruit6" "six"]
["fruit7" "seven"]
["fruit8" "eight"]
["fruit9" "nine"]]
{:batch-size 3})]
(conj result (count (jdbc/execute! (ds) ["select * from fruit"]))))
(finally
(jdbc/execute-one! (ds) ["delete from fruit where id > 4"])))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"])))))
(testing "big batch insert"
(is (= [1 1 1 1 1 1 1 1 1 13]
(try
(let [result (jdbc/execute-batch! (ds)
"INSERT INTO fruit (name, appearance) VALUES (?,?)"
[["fruit1" "one"]
["fruit2" "two"]
["fruit3" "three"]
["fruit4" "four"]
["fruit5" "five"]
["fruit6" "six"]
["fruit7" "seven"]
["fruit8" "eight"]
["fruit9" "nine"]]
{:batch-size 8})]
(conj result (count (jdbc/execute! (ds) ["select * from fruit"]))))
(finally
(jdbc/execute-one! (ds) ["delete from fruit where id > 4"])))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"])))))
(testing "large batch insert"
(when-not (or (jtds?) (sqlite?))
(is (= [1 1 1 1 1 1 1 1 1 13]
(try
(let [result (jdbc/execute-batch! (ds)
"INSERT INTO fruit (name, appearance) VALUES (?,?)"
[["fruit1" "one"]
["fruit2" "two"]
["fruit3" "three"]
["fruit4" "four"]
["fruit5" "five"]
["fruit6" "six"]
["fruit7" "seven"]
["fruit8" "eight"]
["fruit9" "nine"]]
{:batch-size 4
:large true})]
(conj result (count (jdbc/execute! (ds) ["select * from fruit"]))))
(finally
(jdbc/execute-one! (ds) ["delete from fruit where id > 4"])))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"]))))))
(testing "return generated keys"
(when-not (mssql?)
(let [results
(try
(let [result (jdbc/execute-batch! (ds)
"INSERT INTO fruit (name, appearance) VALUES (?,?)"
[["fruit1" "one"]
["fruit2" "two"]
["fruit3" "three"]
["fruit4" "four"]
["fruit5" "five"]
["fruit6" "six"]
["fruit7" "seven"]
["fruit8" "eight"]
["fruit9" "nine"]]
;; note: we need both :return-keys true for creating
;; the PreparedStatement and :return-generated-keys
;; true to control the way batch execution happens:
{:batch-size 4 :return-keys true
:return-generated-keys true})]
(conj result (count (jdbc/execute! (ds) ["select * from fruit"]))))
(finally
(jdbc/execute-one! (ds) ["delete from fruit where id > 4"])))]
(is (= 13 (last results)))
(is (every? map? (butlast results)))
;; Derby and SQLite only return one generated key per batch so there
;; are only three keys, plus the overall count here:
(is (< 3 (count results))))
(is (= 4 (count (jdbc/execute! (ds) ["select * from fruit"])))))))
(deftest folding-test
(jdbc/execute-one! (ds) ["delete from fruit"])
(with-open [con (jdbc/get-connection (ds))