diff --git a/CHANGELOG.md b/CHANGELOG.md index 9c06127..38c6af2 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -6,6 +6,7 @@ Only accretive/fixative changes will be made from now on. The following changes have been committed to the **master** branch since the 1.0.11 release: +* Address #81 by splitting the SQL-building functions out of `next.jdbc.sql` into `next.jdbc.sql.builder`. * Fix #80 by avoiding the auto-commit restore after a failed rollback in a failed transaction. * Address #78 by documenting the `:connectionInitSql` workaround for HikariCP/PostgreSQL and non-default schemas. diff --git a/src/next/jdbc/sql.clj b/src/next/jdbc/sql.clj index 272e0aa..dbbe9b3 100644 --- a/src/next/jdbc/sql.clj +++ b/src/next/jdbc/sql.clj @@ -21,165 +21,13 @@ In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY` clause to the generated SQL." - (:require [clojure.string :as str] - [next.jdbc :refer [execute! execute-one!]])) + (:require [next.jdbc :refer [execute! execute-one!]] + [next.jdbc.sql.builder + :refer [for-delete for-insert for-insert-multi + for-query for-update]])) (set! *warn-on-reflection* true) -(defn- by-keys - "Given a hash map of column names and values and a clause type - (`:set`, `:where`), return a vector of a SQL clause and its parameters. - - Applies any `:column-fn` supplied in the options." - [key-map clause opts] - (let [entity-fn (:column-fn opts identity) - [where params] (reduce-kv (fn [[conds params] k v] - (let [e (entity-fn (name k))] - (if (and (= :where clause) (nil? v)) - [(conj conds (str e " IS NULL")) params] - [(conj conds (str e " = ?")) (conj params v)]))) - [[] []] - key-map)] - (assert (seq where) "key-map may not be empty") - (into [(str (str/upper-case (name clause)) " " - (str/join (if (= :where clause) " AND " ", ") where))] - params))) - -(defn- as-keys - "Given a hash map of column names and values, return a string of all the - column names. - - Applies any `:column-fn` supplied in the options." - [key-map opts] - (str/join ", " (map (comp (:column-fn opts identity) name) (keys key-map)))) - -(defn- as-? - "Given a hash map of column names and values, or a vector of column names, - return a string of `?` placeholders for them." - [key-map opts] - (str/join ", " (repeat (count key-map) "?"))) - -(defn- for-order-col - "Given a column name, or a pair of column name and direction, - return the sub-clause for addition to `ORDER BY`." - [col opts] - (let [entity-fn (:column-fn opts identity)] - (cond (keyword? col) - (entity-fn (name col)) - - (and (vector? col) (= 2 (count col)) (keyword? (first col))) - (str (entity-fn (name (first col))) - " " - (or (get {:asc "ASC" :desc "DESC"} (second col)) - (throw (IllegalArgumentException. - (str ":order-by " col - " expected :asc or :desc"))))) - :else - (throw (IllegalArgumentException. - (str ":order-by expected keyword or keyword pair," - " found: " col)))))) - -(defn- for-order - "Given an `:order-by` vector, return an `ORDER BY` clause." - [order-by opts] - (when-not (vector? order-by) - (throw (IllegalArgumentException. ":order-by must be a vector"))) - (assert (seq order-by) ":order-by may not be empty") - (str "ORDER BY " - (str/join ", " (map #(for-order-col % opts) order-by)))) - -(defn- for-query - "Given a table name and either a hash map of column names and values or a - vector of SQL (where clause) and its parameters, return a vector of the - full `SELECT` SQL string and its parameters. - - Applies any `:table-fn` / `:column-fn` supplied in the options." - [table where-params opts] - (let [entity-fn (:table-fn opts identity) - where-params (if (map? where-params) - (by-keys where-params :where opts) - (into [(str "WHERE " (first where-params))] - (rest where-params)))] - (into [(str "SELECT * FROM " (entity-fn (name table)) - " " (first where-params) - (when-let [order-by (:order-by opts)] - (str " " (for-order order-by opts))))] - (rest where-params)))) - -(defn- for-delete - "Given a table name and either a hash map of column names and values or a - vector of SQL (where clause) and its parameters, return a vector of the - full `DELETE` SQL string and its parameters. - - Applies any `:table-fn` / `:column-fn` supplied in the options." - [table where-params opts] - (let [entity-fn (:table-fn opts identity) - where-params (if (map? where-params) - (by-keys where-params :where opts) - (into [(str "WHERE " (first where-params))] - (rest where-params)))] - (into [(str "DELETE FROM " (entity-fn (name table)) - " " (first where-params))] - (rest where-params)))) - -(defn- for-update - "Given a table name, a vector of column names to set and their values, and - either a hash map of column names and values or a vector of SQL (where clause) - and its parameters, return a vector of the full `UPDATE` SQL string and its - parameters. - - Applies any `:table-fn` / `:column-fn` supplied in the options." - [table key-map where-params opts] - (let [entity-fn (:table-fn opts identity) - set-params (by-keys key-map :set opts) - where-params (if (map? where-params) - (by-keys where-params :where opts) - (into [(str "WHERE " (first where-params))] - (rest where-params)))] - (-> [(str "UPDATE " (entity-fn (name table)) - " " (first set-params) - " " (first where-params))] - (into (rest set-params)) - (into (rest where-params))))) - -(defn- for-insert - "Given a table name and a hash map of column names and their values, - return a vector of the full `INSERT` SQL string and its parameters. - - Applies any `:table-fn` / `:column-fn` supplied in the options." - [table key-map opts] - (let [entity-fn (:table-fn opts identity) - params (as-keys key-map opts) - places (as-? key-map opts)] - (assert (seq key-map) "key-map may not be empty") - (into [(str "INSERT INTO " (entity-fn (name table)) - " (" params ")" - " VALUES (" places ")")] - (vals key-map)))) - -(defn- for-insert-multi - "Given a table name, a vector of column names, and a vector of row values - (each row is a vector of its values), return a vector of the full `INSERT` - SQL string and its parameters. - - Applies any `:table-fn` / `:column-fn` supplied in the options." - [table cols rows opts] - (assert (apply = (count cols) (map count rows)) - "column counts are not consistent across cols and rows") - ;; to avoid generating bad SQL - (assert (seq cols) "cols may not be empty") - (assert (seq rows) "rows may not be empty") - (let [table-fn (:table-fn opts identity) - column-fn (:column-fn opts identity) - params (str/join ", " (map (comp column-fn name) cols)) - places (as-? (first rows) opts)] - (into [(str "INSERT INTO " (table-fn (name table)) - " (" params ")" - " VALUES " - (str/join ", " (repeat (count rows) (str "(" places ")"))))] - cat - rows))) - (defn insert! "Syntactic sugar over `execute-one!` to make inserting hash maps easier. diff --git a/src/next/jdbc/sql/builder.clj b/src/next/jdbc/sql/builder.clj new file mode 100644 index 0000000..ecda634 --- /dev/null +++ b/src/next/jdbc/sql/builder.clj @@ -0,0 +1,190 @@ +;; copyright (c) 2019 Sean Corfield, all rights reserved + +(ns next.jdbc.sql.builder + "Some utility functions for building SQL strings. + + These were originally private functions in `next.jdbc.sql` but + they may proof useful to developers who want to write their own + 'SQL sugar' functions, such as a database-specific `upsert!` etc." + (:require [clojure.string :as str])) + +(set! *warn-on-reflection* true) + +(defn as-? + "Given a hash map of column names and values, or a vector of column names, + return a string of `?` placeholders for them." + [key-map opts] + (str/join ", " (repeat (count key-map) "?"))) + +(defn as-keys + "Given a hash map of column names and values, return a string of all the + column names. + + Applies any `:column-fn` supplied in the options." + [key-map opts] + (str/join ", " (map (comp (:column-fn opts identity) name) (keys key-map)))) + +(defn by-keys + "Given a hash map of column names and values and a clause type + (`:set`, `:where`), return a vector of a SQL clause and its parameters. + + Applies any `:column-fn` supplied in the options." + [key-map clause opts] + (let [entity-fn (:column-fn opts identity) + [where params] (reduce-kv (fn [[conds params] k v] + (let [e (entity-fn (name k))] + (if (and (= :where clause) (nil? v)) + [(conj conds (str e " IS NULL")) params] + [(conj conds (str e " = ?")) (conj params v)]))) + [[] []] + key-map)] + (assert (seq where) "key-map may not be empty") + (into [(str (str/upper-case (name clause)) " " + (str/join (if (= :where clause) " AND " ", ") where))] + params))) + +(defn for-delete + "Given a table name and either a hash map of column names and values or a + vector of SQL (where clause) and its parameters, return a vector of the + full `DELETE` SQL string and its parameters. + + Applies any `:table-fn` / `:column-fn` supplied in the options. + + If `:suffix` is provided in `opts`, that string is appended to the + `DELETE ...` statement." + [table where-params opts] + (let [entity-fn (:table-fn opts identity) + where-params (if (map? where-params) + (by-keys where-params :where opts) + (into [(str "WHERE " (first where-params))] + (rest where-params)))] + (into [(str "DELETE FROM " (entity-fn (name table)) + " " (first where-params) + (when-let [suffix (:suffix opts)] + (str " " suffix)))] + (rest where-params)))) + +(defn for-insert + "Given a table name and a hash map of column names and their values, + return a vector of the full `INSERT` SQL string and its parameters. + + Applies any `:table-fn` / `:column-fn` supplied in the options. + + If `:suffix` is provided in `opts`, that string is appended to the + `INSERT ...` statement." + [table key-map opts] + (let [entity-fn (:table-fn opts identity) + params (as-keys key-map opts) + places (as-? key-map opts)] + (assert (seq key-map) "key-map may not be empty") + (into [(str "INSERT INTO " (entity-fn (name table)) + " (" params ")" + " VALUES (" places ")" + (when-let [suffix (:suffix opts)] + (str " " suffix)))] + (vals key-map)))) + +(defn for-insert-multi + "Given a table name, a vector of column names, and a vector of row values + (each row is a vector of its values), return a vector of the full `INSERT` + SQL string and its parameters. + + Applies any `:table-fn` / `:column-fn` supplied in the options. + + If `:suffix` is provided in `opts`, that string is appended to the + `INSERT ...` statement." + [table cols rows opts] + (assert (apply = (count cols) (map count rows)) + "column counts are not consistent across cols and rows") + ;; to avoid generating bad SQL + (assert (seq cols) "cols may not be empty") + (assert (seq rows) "rows may not be empty") + (let [table-fn (:table-fn opts identity) + column-fn (:column-fn opts identity) + params (str/join ", " (map (comp column-fn name) cols)) + places (as-? (first rows) opts)] + (into [(str "INSERT INTO " (table-fn (name table)) + " (" params ")" + " VALUES " + (str/join ", " (repeat (count rows) (str "(" places ")"))) + (when-let [suffix (:suffix opts)] + (str " " suffix)))] + cat + rows))) + +(defn for-order-col + "Given a column name, or a pair of column name and direction, + return the sub-clause for addition to `ORDER BY`." + [col opts] + (let [entity-fn (:column-fn opts identity)] + (cond (keyword? col) + (entity-fn (name col)) + + (and (vector? col) (= 2 (count col)) (keyword? (first col))) + (str (entity-fn (name (first col))) + " " + (or (get {:asc "ASC" :desc "DESC"} (second col)) + (throw (IllegalArgumentException. + (str ":order-by " col + " expected :asc or :desc"))))) + :else + (throw (IllegalArgumentException. + (str ":order-by expected keyword or keyword pair," + " found: " col)))))) + +(defn for-order + "Given an `:order-by` vector, return an `ORDER BY` clause." + [order-by opts] + (when-not (vector? order-by) + (throw (IllegalArgumentException. ":order-by must be a vector"))) + (assert (seq order-by) ":order-by may not be empty") + (str "ORDER BY " + (str/join ", " (map #(for-order-col % opts) order-by)))) + +(defn for-query + "Given a table name and either a hash map of column names and values or a + vector of SQL (where clause) and its parameters, return a vector of the + full `SELECT` SQL string and its parameters. + + Applies any `:table-fn` / `:column-fn` supplied in the options. + + If `:suffix` is provided in `opts`, that string is appended to the + `SELECT ...` statement." + [table where-params opts] + (let [entity-fn (:table-fn opts identity) + where-params (if (map? where-params) + (by-keys where-params :where opts) + (into [(str "WHERE " (first where-params))] + (rest where-params)))] + (into [(str "SELECT * FROM " (entity-fn (name table)) + " " (first where-params) + (when-let [order-by (:order-by opts)] + (str " " (for-order order-by opts))) + (when-let [suffix (:suffix opts)] + (str " " suffix)))] + (rest where-params)))) + +(defn for-update + "Given a table name, a vector of column names to set and their values, and + either a hash map of column names and values or a vector of SQL (where clause) + and its parameters, return a vector of the full `UPDATE` SQL string and its + parameters. + + Applies any `:table-fn` / `:column-fn` supplied in the options. + + If `:suffix` is provided in `opts`, that string is appended to the + `UPDATE ...` statement." + [table key-map where-params opts] + (let [entity-fn (:table-fn opts identity) + set-params (by-keys key-map :set opts) + where-params (if (map? where-params) + (by-keys where-params :where opts) + (into [(str "WHERE " (first where-params))] + (rest where-params)))] + (-> [(str "UPDATE " (entity-fn (name table)) + " " (first set-params) + " " (first where-params) + (when-let [suffix (:suffix opts)] + (str " " suffix)))] + (into (rest set-params)) + (into (rest where-params))))) diff --git a/test/next/jdbc/sql/builder_test.clj b/test/next/jdbc/sql/builder_test.clj new file mode 100644 index 0000000..8fac109 --- /dev/null +++ b/test/next/jdbc/sql/builder_test.clj @@ -0,0 +1,96 @@ +;; copyright (c) 2019 Sean Corfield, all rights reserved + +(ns next.jdbc.sql.builder-test + "Tests for the SQL string building functions in next.jdbc.sql.builder." + (:require [clojure.test :refer [deftest is testing use-fixtures]] + [next.jdbc.quoted :refer [mysql sql-server]] + [next.jdbc.sql.builder :as builder])) + +(set! *warn-on-reflection* true) + +(deftest test-by-keys + (testing ":where clause" + (is (= (builder/by-keys {:a nil :b 42 :c "s"} :where {}) + ["WHERE a IS NULL AND b = ? AND c = ?" 42 "s"]))) + (testing ":set clause" + (is (= (builder/by-keys {:a nil :b 42 :c "s"} :set {}) + ["SET a = ?, b = ?, c = ?" nil 42 "s"])))) + +(deftest test-as-keys + (is (= (builder/as-keys {:a nil :b 42 :c "s"} {}) + "a, b, c"))) + +(deftest test-as-? + (is (= (builder/as-? {:a nil :b 42 :c "s"} {}) + "?, ?, ?"))) + +(deftest test-for-query + (testing "by example" + (is (= (builder/for-query + :user + {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) + ["SELECT * FROM [user] WHERE `id` = ? ORDER BY `a`, `b` DESC" 9])) + (is (= (builder/for-query :user {:id nil} {:table-fn sql-server :column-fn mysql}) + ["SELECT * FROM [user] WHERE `id` IS NULL"])) + (is (= (builder/for-query :user + {:id nil} + {:table-fn sql-server :column-fn mysql + :suffix "FOR UPDATE"}) + ["SELECT * FROM [user] WHERE `id` IS NULL FOR UPDATE"]))) + (testing "by where clause" + (is (= (builder/for-query + :user + ["id = ? and opt is null" 9] + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) + [(str "SELECT * FROM [user] WHERE id = ? and opt is null" + " ORDER BY `a`, `b` DESC") 9])))) + +(deftest test-for-delete + (testing "by example" + (is (= (builder/for-delete + :user + {:opt nil :id 9} + {:table-fn sql-server :column-fn mysql}) + ["DELETE FROM [user] WHERE `opt` IS NULL AND `id` = ?" 9]))) + (testing "by where clause" + (is (= (builder/for-delete + :user + ["id = ? and opt is null" 9] + {:table-fn sql-server :column-fn mysql}) + ["DELETE FROM [user] WHERE id = ? and opt is null" 9])))) + +(deftest test-for-update + (testing "empty example (would be a SQL error)" + (is (thrown? AssertionError ; changed in #44 + (builder/for-update :user + {:status 42} + {} + {:table-fn sql-server :column-fn mysql})))) + (testing "by example" + (is (= (builder/for-update :user + {:status 42} + {:id 9} + {:table-fn sql-server :column-fn mysql}) + ["UPDATE [user] SET `status` = ? WHERE `id` = ?" 42 9]))) + (testing "by where clause, with nil set value" + (is (= (builder/for-update :user + {:status 42, :opt nil} + ["id = ?" 9] + {:table-fn sql-server :column-fn mysql}) + ["UPDATE [user] SET `status` = ?, `opt` = ? WHERE id = ?" 42 nil 9])))) + +(deftest test-for-inserts + (testing "single insert" + (is (= (builder/for-insert :user + {:id 9 :status 42 :opt nil} + {:table-fn sql-server :column-fn mysql}) + ["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil]))) + (testing "multi-row insert" + (is (= (builder/for-insert-multi :user + [:id :status] + [[42 "hello"] + [35 "world"] + [64 "dollars"]] + {:table-fn sql-server :column-fn mysql}) + ["INSERT INTO [user] (`id`, `status`) VALUES (?, ?), (?, ?), (?, ?)" 42 "hello" 35 "world" 64 "dollars"])))) diff --git a/test/next/jdbc/sql_test.clj b/test/next/jdbc/sql_test.clj index 3dcb361..57df38e 100644 --- a/test/next/jdbc/sql_test.clj +++ b/test/next/jdbc/sql_test.clj @@ -1,11 +1,8 @@ ;; copyright (c) 2019 Sean Corfield, all rights reserved (ns next.jdbc.sql-test - "Tests for the (private) SQL string building functions in next.jdbc.sql. - - At some future date, tests for the syntactic sugar functions will be added." + "Tests for the syntactic sugar SQL functions." (:require [clojure.test :refer [deftest is testing use-fixtures]] - [next.jdbc.quoted :refer [mysql sql-server]] [next.jdbc.specs :as specs] [next.jdbc.sql :as sql] [next.jdbc.test-fixtures @@ -18,66 +15,6 @@ (specs/instrument) -(deftest test-by-keys - (testing ":where clause" - (is (= (#'sql/by-keys {:a nil :b 42 :c "s"} :where {}) - ["WHERE a IS NULL AND b = ? AND c = ?" 42 "s"]))) - (testing ":set clause" - (is (= (#'sql/by-keys {:a nil :b 42 :c "s"} :set {}) - ["SET a = ?, b = ?, c = ?" nil 42 "s"])))) - -(deftest test-as-keys - (is (= (#'sql/as-keys {:a nil :b 42 :c "s"} {}) - "a, b, c"))) - -(deftest test-as-? - (is (= (#'sql/as-? {:a nil :b 42 :c "s"} {}) - "?, ?, ?"))) - -(deftest test-for-query - (testing "by example" - (is (= (#'sql/for-query :user {:id 9} - {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) - ["SELECT * FROM [user] WHERE `id` = ? ORDER BY `a`, `b` DESC" 9])) - (is (= (#'sql/for-query :user {:id nil} {:table-fn sql-server :column-fn mysql}) - ["SELECT * FROM [user] WHERE `id` IS NULL"]))) - (testing "by where clause" - (is (= (#'sql/for-query :user ["id = ? and opt is null" 9] - {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) - [(str "SELECT * FROM [user] WHERE id = ? and opt is null" - " ORDER BY `a`, `b` DESC") 9])))) - -(deftest test-for-delete - (testing "by example" - (is (= (#'sql/for-delete :user {:opt nil :id 9} {:table-fn sql-server :column-fn mysql}) - ["DELETE FROM [user] WHERE `opt` IS NULL AND `id` = ?" 9]))) - (testing "by where clause" - (is (= (#'sql/for-delete :user ["id = ? and opt is null" 9] {:table-fn sql-server :column-fn mysql}) - ["DELETE FROM [user] WHERE id = ? and opt is null" 9])))) - -(deftest test-for-update - (testing "empty example (would be a SQL error)" - (is (thrown? AssertionError ; changed in #44 - (#'sql/for-update :user {:status 42} {} {:table-fn sql-server :column-fn mysql})))) - (testing "by example" - (is (= (#'sql/for-update :user {:status 42} {:id 9} {:table-fn sql-server :column-fn mysql}) - ["UPDATE [user] SET `status` = ? WHERE `id` = ?" 42 9]))) - (testing "by where clause, with nil set value" - (is (= (#'sql/for-update :user {:status 42, :opt nil} ["id = ?" 9] {:table-fn sql-server :column-fn mysql}) - ["UPDATE [user] SET `status` = ?, `opt` = ? WHERE id = ?" 42 nil 9])))) - -(deftest test-for-inserts - (testing "single insert" - (is (= (#'sql/for-insert :user {:id 9 :status 42 :opt nil} {:table-fn sql-server :column-fn mysql}) - ["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil]))) - (testing "multi-row insert" - (is (= (#'sql/for-insert-multi :user [:id :status] - [[42 "hello"] - [35 "world"] - [64 "dollars"]] - {:table-fn sql-server :column-fn mysql}) - ["INSERT INTO [user] (`id`, `status`) VALUES (?, ?), (?, ?), (?, ?)" 42 "hello" 35 "world" 64 "dollars"])))) - (deftest test-query (let [rs (sql/query (ds) ["select * from fruit order by id"] (default-options))]