diff --git a/CHANGELOG.md b/CHANGELOG.md index 15e345d..d5c3d61 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -7,6 +7,7 @@ Only accretive/fixative changes will be made from now on. Changes made since the 1.0.478 release: * Address #125 by making the result of `plan` foldable (in the `clojure.core.reducers` sense). * Address #124 by extending `next.jdbc.sql.builder/for-query` to support `:top` (SQL Server), `:limit` / `:offset` (MySQL/PostgreSQL), `:offset` / `:fetch` (SQL Standard). +* Address #116 by adding a `:multi-rs` option to `execute!` to retrieve multiple result sets, for example from stored procedure calls or T-SQL scripts. * Allow `:all` to be passed into `find-by-keys` instead of an example hash map or a where clause vector so all rows will be returned (expected to be used with `:offset` etc to support simple pagination of an entire table). * Add `:columns` option to `find-by-keys` (and `get-by-id`) to specify a subset of columns to be returned in each row. This can also specify an alias for the column and allows for computed expressions to be selected with an alias. diff --git a/doc/all-the-options.md b/doc/all-the-options.md index e9608fe..e233df2 100644 --- a/doc/all-the-options.md +++ b/doc/all-the-options.md @@ -59,6 +59,8 @@ Any function that might realize a row or a result set will accept: * `:label-fn` -- if `:builder-fn` is specified as one of `next.jdbc.result-set`'s `as-modified-*` builders, this option must be present and should specify a string-to-string transformation that will be applied to the column label for each returned column name. * `:qualifier-fn` -- if `:builder-fn` is specified as one of `next.jdbc.result-set`'s `as-modified-*` builders, this option should specify a string-to-string transformation that will be applied to the table name for each returned column name. It will be called with an empty string if the table name is not available. It can be omitted for the `as-unqualified-modified-*` variants. +In addition, `execute!` accepts the `:multi-rs true` option to return multiple result sets -- as a vector of result sets. + > Note: Subject to the caveats above about `:builder-fn`, that means that `plan`, `execute!`, `execute-one!`, and the "friendly" SQL functions will all accept these options for generating rows and result sets. ## Statements & Prepared Statements diff --git a/doc/getting-started.md b/doc/getting-started.md index 5d39e28..61b65dd 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -93,6 +93,8 @@ 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. + > 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. ### Options & Result Set Builders diff --git a/src/next/jdbc.clj b/src/next/jdbc.clj index b46283f..9b04e92 100644 --- a/src/next/jdbc.clj +++ b/src/next/jdbc.clj @@ -214,7 +214,10 @@ (defn execute! "General SQL execution function. - Returns a fully-realized result set. + Returns a fully-realized result set. When `:multi-rs true` is provided, will + return multiple result sets, as a vector of result sets. Each result set is + a vector of hash maps, by default, but can be controlled by the `:builder-fn` + option. Can be called on a `PreparedStatement`, a `Connection`, or something that can produce a `Connection` via a `DataSource`." diff --git a/src/next/jdbc/result_set.clj b/src/next/jdbc/result_set.clj index 98dd9da..810b930 100644 --- a/src/next/jdbc/result_set.clj +++ b/src/next/jdbc/result_set.clj @@ -584,6 +584,26 @@ (.getGeneratedKeys stmt) (catch Exception _))))) +(defn- stmt->result-set-update-count + "Given a connectable, a `Statement`, a flag indicating there might + be a result set, and options, return a (datafiable) result set if possible + (either from the statement or from generated keys). If no result set is + available, return a 'fake' result set containing the update count. + + If no update count is available either, return nil." + [connectable ^Statement stmt go opts] + (if-let [^ResultSet + rs (if go + (.getResultSet stmt) + (when (:return-keys opts) + (try + (.getGeneratedKeys stmt) + (catch Exception _))))] + (datafiable-result-set rs connectable opts) + (let [n (.getUpdateCount stmt)] + (when-not (= -1 n) + [{:next.jdbc/update-count n}])))) + (defn- reduce-stmt "Execute the `PreparedStatement`, attempt to get either its `ResultSet` or its generated keys (as a `ResultSet`), and reduce that using the supplied @@ -658,8 +678,8 @@ (reducef (combinef) {:next.jdbc/update-count (.getUpdateCount stmt)}))) (defn- stmt-sql->result-set - "Given a `Statement`, a SQL command, and options, execute it and return a - `ResultSet` if possible." + "Given a `Statement`, a SQL command, execute it and return a + `ResultSet` if possible. We always attempt to return keys." ^ResultSet [^Statement stmt ^String sql] (if (.execute stmt sql) @@ -758,9 +778,14 @@ (first sql-params) (rest sql-params) opts)] - (if-let [rs (stmt->result-set stmt opts)] - (datafiable-result-set rs this opts) - [{:next.jdbc/update-count (.getUpdateCount stmt)}]))) + (if (:multi-rs opts) + (loop [go (.execute stmt) acc []] + (if-let [rs (stmt->result-set-update-count this stmt go opts)] + (recur (.getMoreResults stmt) (conj acc rs)) + acc)) + (if-let [rs (stmt->result-set stmt opts)] + (datafiable-result-set rs this opts) + [{:next.jdbc/update-count (.getUpdateCount stmt)}])))) javax.sql.DataSource (-execute [this sql-params opts] @@ -800,9 +825,14 @@ (first sql-params) (rest sql-params) opts)] + (if (:multi-rs opts) + (loop [go (.execute stmt) acc []] + (if-let [rs (stmt->result-set-update-count this stmt go opts)] + (recur (.getMoreResults stmt) (conj acc rs)) + acc)) (if-let [rs (stmt->result-set stmt opts)] (datafiable-result-set rs this opts) - [{:next.jdbc/update-count (.getUpdateCount stmt)}]))) + [{:next.jdbc/update-count (.getUpdateCount stmt)}])))) java.sql.PreparedStatement ;; we can't tell if this PreparedStatement will return generated @@ -827,9 +857,15 @@ (.getConnection this) opts))) {:next.jdbc/update-count (.getUpdateCount this)})) (-execute-all [this _ opts] - (if-let [rs (stmt->result-set this opts)] - (datafiable-result-set rs (.getConnection this) opts) - [{:next.jdbc/update-count (.getUpdateCount this)}])) + (if (:multi-rs opts) + (loop [go (.execute this) acc []] + (if-let [rs (stmt->result-set-update-count + (.getConnection this) this go (assoc opts :return-keys true))] + (recur (.getMoreResults this) (conj acc rs)) + acc)) + (if-let [rs (stmt->result-set this (assoc opts :return-keys true))] + (datafiable-result-set rs (.getConnection this) opts) + [{:next.jdbc/update-count (.getUpdateCount this)}]))) java.sql.Statement (-execute [this sql-params opts] @@ -857,9 +893,15 @@ (-execute-all [this sql-params opts] (assert (= 1 (count sql-params)) "Parameters cannot be provided when executing a non-prepared Statement") - (if-let [rs (stmt-sql->result-set this (first sql-params))] - (datafiable-result-set rs (.getConnection this) opts) - [{:next.jdbc/update-count (.getUpdateCount this)}])) + (if (:multi-rs opts) + (loop [go (.execute this (first sql-params)) acc []] + (if-let [rs (stmt->result-set-update-count + (.getConnection this) this go (assoc opts :return-keys true))] + (recur (.getMoreResults this) (conj acc rs)) + acc)) + (if-let [rs (stmt-sql->result-set this (first sql-params))] + (datafiable-result-set rs (.getConnection this) opts) + [{:next.jdbc/update-count (.getUpdateCount this)}]))) Object (-execute [this sql-params opts] diff --git a/test/next/jdbc/test_fixtures.clj b/test/next/jdbc/test_fixtures.clj index 5b78806..37df885 100644 --- a/test/next/jdbc/test_fixtures.clj +++ b/test/next/jdbc/test_fixtures.clj @@ -58,6 +58,8 @@ (defn derby? [] (= "derby" (:dbtype @test-db-spec))) +(defn hsqldb? [] (= "hsqldb" (:dbtype @test-db-spec))) + (defn jtds? [] (= "jtds" (:dbtype @test-db-spec))) (defn maria? [] (= "mariadb" (:dbtype @test-db-spec))) @@ -70,6 +72,8 @@ (defn sqlite? [] (= "sqlite" (:dbtype @test-db-spec))) +(defn stored-proc? [] (not (#{"derby" "h2" "h2:mem" "sqlite"} (:dbtype @test-db-spec)))) + (defn column [k] (let [n (namespace k)] (keyword (when n (cond (postgres?) (str/lower-case n) @@ -121,7 +125,7 @@ (reset! test-datasource (jdbc/get-datasource db))) (let [fruit (if (mysql?) "fruit" "FRUIT") ; MySQL is case sensitive! auto-inc-pk - (cond (or (derby?) (= "hsqldb" (:dbtype db))) + (cond (or (derby?) (hsqldb?)) (str "GENERATED ALWAYS AS IDENTITY" " (START WITH 1, INCREMENT BY 1)" " PRIMARY KEY") @@ -135,6 +139,10 @@ :else "AUTO_INCREMENT PRIMARY KEY")] (with-open [con (jdbc/get-connection (ds))] + (when (stored-proc?) + (try + (jdbc/execute-one! con ["DROP PROCEDURE FRUITP"]) + (catch Throwable _))) (try (do-commands con [(str "DROP TABLE " fruit)]) (catch Exception _)) @@ -158,14 +166,35 @@ CREATE TABLE " fruit " ( COST INT DEFAULT NULL, GRADE REAL DEFAULT NULL )")]) - (sql/insert-multi! con :fruit - [:name :appearance :cost :grade] - [["Apple" "red" 59 nil] - ["Banana" "yellow" nil 92.2] - ["Peach" nil 139 90.0] - ["Orange" "juicy" 89 88.6]] - {:return-keys false}) - (t))))) + (when (stored-proc?) + (let [[begin end] (if (postgres?) ["$$" "$$"] ["BEGIN" "END"])] + (try + (do-commands con [(str " +CREATE PROCEDURE FRUITP" (cond (hsqldb?) "() READS SQL DATA DYNAMIC RESULT SETS 2 " + (mssql?) " AS " + (postgres?) "() LANGUAGE SQL AS " + :else "() ") " + " begin " " (if (hsqldb?) + (str "ATOMIC + DECLARE result1 CURSOR WITH RETURN FOR SELECT * FROM " fruit " WHERE COST < 90; + DECLARE result2 CURSOR WITH RETURN FOR SELECT * FROM " fruit " WHERE GRADE >= 90.0; + OPEN result1; + OPEN result2;") + (str " + SELECT * FROM " fruit " WHERE COST < 90; + SELECT * FROM " fruit " WHERE GRADE >= 90.0;")) " + " end " +")]) + (catch Throwable t + (println 'procedure (:dbtype db) (ex-message t)))))) + (sql/insert-multi! con :fruit + [:name :appearance :cost :grade] + [["Apple" "red" 59 nil] + ["Banana" "yellow" nil 92.2] + ["Peach" nil 139 90.0] + ["Orange" "juicy" 89 88.6]] + {:return-keys false}) + (t))))) (comment ;; this is a convenience to bring next.jdbc's test dependencies diff --git a/test/next/jdbc/transaction_test.clj b/test/next/jdbc/transaction_test.clj index 2c2c852..891c8d0 100644 --- a/test/next/jdbc/transaction_test.clj +++ b/test/next/jdbc/transaction_test.clj @@ -2,7 +2,16 @@ (ns next.jdbc.transaction-test "Stub test namespace for transaction handling." - (:require [clojure.test :refer [deftest is testing]] - [next.jdbc.transaction :refer :all])) + (:require [clojure.test :refer [deftest is testing use-fixtures]] + [next.jdbc :as jdbc] + [next.jdbc.specs :as specs] + [next.jdbc.test-fixtures :refer [with-test-db db ds column + default-options + derby? mssql? mysql? postgres?]] + [next.jdbc.transaction :as tx])) (set! *warn-on-reflection* true) + +(use-fixtures :once with-test-db) + +(specs/instrument) diff --git a/test/next/jdbc_test.clj b/test/next/jdbc_test.clj index 1f56663..0d9bfcf 100644 --- a/test/next/jdbc_test.clj +++ b/test/next/jdbc_test.clj @@ -7,9 +7,10 @@ [clojure.test :refer [deftest is testing use-fixtures]] [next.jdbc :as jdbc] [next.jdbc.connection :as c] - [next.jdbc.test-fixtures :refer [with-test-db db ds column - default-options - derby? jtds? mssql? mysql? postgres?]] + [next.jdbc.test-fixtures + :refer [with-test-db db ds column + default-options stored-proc? + derby? hsqldb? jtds? mssql? mysql? postgres?]] [next.jdbc.prepare :as prep] [next.jdbc.result-set :as rs] [next.jdbc.specs :as specs]) @@ -369,6 +370,44 @@ VALUES ('Pear', 'green', 49, 47) (with-open [con (jdbc/get-connection ds {})] (is (instance? java.sql.Connection con))))))) +(deftest multi-rs + (when (mssql?) + (testing "script with multiple result sets" + (let [multi-rs + (jdbc/execute! (ds) + [(str "begin" + " select * from fruit;" + " select * from fruit where id < 4;" + " end")] + {: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 + (let [multi-rs + (jdbc/execute! (ds) + [(if (mssql?) "EXEC FRUITP" "CALL FRUITP()")] + {:multi-rs true}) + zero-updates [{:next.jdbc/update-count 0}]] + (cond (postgres?) ; does not support multiple result sets yet + (do + (is (= 1 (count multi-rs))) + (is (= zero-updates (first multi-rs)))) + (hsqldb?) + (do + (is (= 3 (count multi-rs))) + (is (= zero-updates (first multi-rs)))) + (mysql?) + (do + (is (= 3 (count multi-rs))) + (is (= zero-updates (last multi-rs)))) + :else + (is (= 2 (count multi-rs))))) + (catch Throwable t + (println 'call-proc (:dbtype (db)) (ex-message t) (some-> t (ex-cause) (ex-message)))))))) + (deftest plan-misuse (let [s (pr-str (jdbc/plan (ds) ["select * from fruit"]))] (is (re-find #"missing reduction" s)))