diff --git a/CHANGELOG.md b/CHANGELOG.md index 9d08a26..583ee7e 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -6,6 +6,7 @@ Only accretive/fixative changes will be made from now on. * 1.1.next in progress * Documented `next.jdbc.transaction/*nested-tx*` more thoroughly since that difference from `clojure.java.jdbc` has come up in conversation a few times recently. + * Fix #158 by documenting (and testing) `:allowMultiQueries true` as an option for MySQL/MariaDB to allow multiple statements to be executed and multiple result sets to be returned. * Fix #157 by copying `next.jdbc.prepare/execute-batch!` to `next.jdbc/execute-batch!` (to avoid a circular dependency that previously relied on requiring `next.jdbc.result-set` at runtime -- which was problematic for GraalVM-based native compilation); **`next.jdbc.prepare/execute-batch!` is deprecated:** it will continue to exist and work, but is no longer documented. In addition, `next.jdbc.prepare/execute-batch!` now relies on a private `volatile!` in order to reference `next.jdbc.result-set/datafiable-result-set` so that it is GraalVM-friendly. Note: code that requires `next.jdbc.prepare` and uses `execute-batch!` without also requiring something that causes `next.jdbc.result-set` to be loaded will no longer return generated keys from `execute-batch!` but that's an almost impossible path since nearly all code that uses `execute-batch!` will have called `next.jdbc/prepare` to get the `PreparedStatement` in the first place. * 1.1.613 -- 2020-11-05 diff --git a/doc/getting-started.md b/doc/getting-started.md index e7334ad..05fd3e0 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -95,7 +95,7 @@ Since we used `execute-one!`, we get just one row back (a hash map). This also s If the result set contains no rows, `execute-one!` returns `nil`. When no result is available, and `next.jdbc` returns a fake "result set" containing the "update count", `execute-one!` returns just a single hash map with the key `next.jdbc/update-count` and the number of rows updated. -In the same way that you would use `execute-one!` if you only want one row or one update count, compared to `execute!` for multiple rows or a vector containing an update count, you can also ask `execute!` to return multiple result sets -- such as might be returned from a stored procedure call, or a T-SQL script (for SQL Server) -- instead of just one. If you pass the `:multi-rs true` option to `execute!`, you will get back a vector of results sets, instead of just one result set: a vector of zero or more vectors. The result may well be a mix of vectors containing realized rows and vectors containing update counts, reflecting the results from specific SQL operations in the stored procedure or script. +In the same way that you would use `execute-one!` if you only want one row or one update count, compared to `execute!` for multiple rows or a vector containing an update count, you can also ask `execute!` to return multiple result sets -- such as might be returned from a stored procedure call, or a T-SQL script (for SQL Server), or multiple statements (for MySQL) -- instead of just one. If you pass the `:multi-rs true` option to `execute!`, you will get back a vector of results sets, instead of just one result set: a vector of zero or more vectors. The result may well be a mix of vectors containing realized rows and vectors containing update counts, reflecting the results from specific SQL operations in the stored procedure or script. > Note: In general, you should use `execute-one!` for DDL operations since you will only get back an update count. If you have a SQL statement that you know will only return an update count, `execute-one!` is the right choice. If you have a SQL statement that you know will only return a single row in the result set, you probably want to use `execute-one!`. If you use `execute-one!` for a SQL statement that would return multiple rows in a result set, even though you will only get the first row back (as a hash map), the full result set will still be retrieved from the database -- it does not limit the SQL in any way. diff --git a/doc/tips-and-tricks.md b/doc/tips-and-tricks.md index 6f75106..010c7ff 100644 --- a/doc/tips-and-tricks.md +++ b/doc/tips-and-tricks.md @@ -91,6 +91,15 @@ In MS SQL Server, the generated key from an insert comes back as `:GENERATED_KEY By default, you won't get table names as qualifiers with Microsoft's JDBC driver (you might with the jTDS drive -- I haven't tried that recently). See this [MSDN forum post about `.getTableName()`](https://social.msdn.microsoft.com/Forums/sqlserver/en-US/55e8cbb2-b11c-446e-93ab-dc30658caf99/resultsetmetadatagettablename-returns-instead-of-table-name) for details. According to one of the answers posted there, if you specify `:result-type` and `:concurrency` in the options for `execute!`, `execute-one!`, `plan`, or `prepare`, that will cause SQL Server to return table names for columns. `:result-type` needs to be `:scoll-sensitive` or `:scroll-insensitive` for this to work. `:concurrency` can be `:read-only` or `:updatable`. +MS SQL Server supports execution of multiple statements when surrounded by `begin`/`end` and can return multiple result sets, when requested via `:multi-rs true` on `execute!`. + +```clojure +(jdbc/execute! db-spec ["begin select * from table1; select * from table2; end"] {:multi-rs true}) +;; vector of result sets: +=> [[{.. table1 row ..} {.. table1 row ..}] + [{.. table2 row ..} {.. table2 row ..} {..}]] +``` + ## MySQL & MariaDB In MySQL, the generated key from an insert comes back as `:GENERATED_KEY`. In MariaDB, the generated key from an insert comes back as `:insert_id`. @@ -99,6 +108,19 @@ MySQL generally stores tables as files so they are case-sensitive if your O/S is It's also worth noting that column comparisons are case-insensitive so `WHERE foo = 'BAR'` will match `"bar"` or `"BAR"` etc. +MySQL has a connection option, `:allowMultiQueries true`, that allows you to pass multiple SQL statements in a single operation and can return multiple result sets, when requested via `:multi-rs true`. + +```clojure +(def db-spec {:dbtype "mysql" .. :allowMultiQueries true}) +;; equivalent to allowMultiQueries=true in the JDBC URL +(jdbc/execute! db-spec ["select * from table1; select * from table2"] {:multi-rs true}) +;; vector of result sets: +=> [[{.. table1 row ..} {.. table1 row ..}] + [{.. table2 row ..} {.. table2 row ..} {..}]] +``` + +Compare this with MS SQL Server above: MySQL does not support `begin`/`end` here. This is not the default behavior because allowing multiple statements in a single operation is generally considered a bit of a risk as it can make it easier for SQL injection attacks to be performed. + ### Batch Statements Even when using `next.jdbc/execute-batch!`, MySQL will still send multiple statements to the database unless you specify `:rewriteBatchedStatements true` as part of the db-spec hash map or JDBC URL when the datasource is created. diff --git a/test/next/jdbc/test_fixtures.clj b/test/next/jdbc/test_fixtures.clj index 220f26e..f5515cd 100644 --- a/test/next/jdbc/test_fixtures.clj +++ b/test/next/jdbc/test_fixtures.clj @@ -31,7 +31,7 @@ (merge (if (System/getenv "NEXT_JDBC_TEST_MARIADB") {:dbtype "mariadb"} {:dbtype "mysql" :disableMariaDbDriver true}) - {:dbname "clojure_test" :useSSL false + {:dbname "clojure_test" :useSSL false :allowMultiQueries true :user "root" :password (System/getenv "MYSQL_ROOT_PASSWORD")})) (def ^:private test-mysql (when (System/getenv "NEXT_JDBC_TEST_MYSQL") test-mysql-map)) diff --git a/test/next/jdbc_test.clj b/test/next/jdbc_test.clj index 24b0c41..945d106 100644 --- a/test/next/jdbc_test.clj +++ b/test/next/jdbc_test.clj @@ -643,7 +643,7 @@ INSERT INTO fruit (name, appearance) VALUES (?,?) ds (jdbc/get-datasource (assoc etc :jdbcUrl url))] (cond (derby?) (is (= {:create true} etc)) (mssql?) (is (= #{:user :password} (set (keys etc)))) - (mysql?) (is (= #{:user :password :useSSL} + (mysql?) (is (= #{:user :password :useSSL :allowMultiQueries} (disj (set (keys etc)) :disableMariaDbDriver))) :else (is (= {} etc))) (is (instance? javax.sql.DataSource ds)) @@ -672,6 +672,16 @@ INSERT INTO fruit (name, appearance) VALUES (?,?) (is (= 2 (count multi-rs))) (is (= 4 (count (first multi-rs)))) (is (= 3 (count (second multi-rs))))))) + (when (mysql?) + (testing "script with multiple result sets" + (let [multi-rs + (jdbc/execute! (ds) + [(str "select * from fruit;" + " select * from fruit where id < 4")] + {:multi-rs true})] + (is (= 2 (count multi-rs))) + (is (= 4 (count (first multi-rs)))) + (is (= 3 (count (second multi-rs))))))) (when (stored-proc?) (testing "stored proc; multiple result sets" (try