From 1bd4bdedce465761bd2575aa7bf10f6cc71f5067 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 29 Jun 2024 13:09:13 -0700 Subject: [PATCH] fixes #269 by adding :name-fn option Signed-off-by: Sean Corfield --- CHANGELOG.md | 1 + doc/all-the-options.md | 3 + src/next/jdbc/result_set.clj | 5 +- src/next/jdbc/sql/builder.clj | 53 +++++---- test/next/jdbc/sql/builder_test.clj | 160 ++++++++++++++++++++++++++-- 5 files changed, 191 insertions(+), 31 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 9a42f13..b7e3917 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -3,6 +3,7 @@ Only accretive/fixative changes will be made from now on. * 1.3.next in progress + * Address [#269](https://github.com/seancorfield/next-jdbc/issues/269) by adding `:name-fn` as an option (primarily for the SQL builder functions, but also for result set processing); the default is `clojure.core/name` but you can now use `next.jdbc.sql.builder/qualified-name` to preserve the qualifier. * Update testing deps. * 1.3.939 -- 2024-05-17 diff --git a/doc/all-the-options.md b/doc/all-the-options.md index c4487ae..3bc4af3 100644 --- a/doc/all-the-options.md +++ b/doc/all-the-options.md @@ -41,6 +41,7 @@ Except for `query` (which is simply an alias for `execute!`), all the "friendly" * `:table-fn` -- the quoting function to be used on the string that identifies the table name, if provided; this also applies to assumed table names when `nav`igating schemas, * `:column-fn` -- the quoting function to be used on any string that identifies a column name, if provided; this also applies to the reducing function context over `plan` and to assumed foreign key column names when `nav`igating schemas. +* `:name-fn` -- may be provided as `next.jdbc.sql.builder/qualified-name` to preserve qualifiers on table and column names; you will need to provide `:table-fn` and/or `:column-fn` as well, in order to quote qualified names properly; new in 1.3.next. They also support a `:suffix` argument which can be used to specify a SQL string that should be appended to the generated SQL string before executing it, e.g., `:suffix "FOR UPDATE"` or, for an `insert!` call `:suffix "RETURNING *"`. The latter is particularly useful for databases, such as SQLite these days, @@ -69,6 +70,8 @@ Any function that might realize a row or a result set will accept: * `:builder-fn` -- a function that implements the `RowBuilder` and `ResultSetBuilder` protocols; strictly speaking, `plan` and `execute-one!` only need `RowBuilder` to be implemented (and `plan` only needs that if it actually has to realize a row) but most generation functions will implement both for ease of use. * `: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. +* `:column-fn` -- if present, applied to each column name before looking up the column in the `ResultSet` to get that column's value. +* `:name-fn` -- may be provided as `next.jdbc.sql.builder/qualified-name` to preserve qualifiers on keyword used as column names; by default, a keyword like `:foo/bar` is treated as `"bar"` when looking up columns in a `ResultSet`; `:name-fn` allows you to refer to column names that contain `/`, which some databases allow; if both `:name-fn` and `:column-fn` are provided, `:name-fn` is applied first to the keyword (to produce a string) and then `:column-fn` is applied to that; new in 1.3.next. In addition, `execute!` accepts the `:multi-rs true` option to return multiple result sets -- as a vector of result sets. diff --git a/src/next/jdbc/result_set.clj b/src/next/jdbc/result_set.clj index 0dd993a..5810507 100644 --- a/src/next/jdbc/result_set.clj +++ b/src/next/jdbc/result_set.clj @@ -486,9 +486,10 @@ (metadata-preserving) operations on it." [^ResultSet rs opts] (let [builder (delay ((get opts :builder-fn as-maps) rs opts)) + name-fn (:name-fn opts name) name-fn (if (contains? opts :column-fn) - (comp (get opts :column-fn) name) - name)] + (comp (get opts :column-fn) name-fn) + name-fn)] (reify MapifiedResultSet diff --git a/src/next/jdbc/sql/builder.clj b/src/next/jdbc/sql/builder.clj index df6c8ff..94938df 100644 --- a/src/next/jdbc/sql/builder.clj +++ b/src/next/jdbc/sql/builder.clj @@ -1,4 +1,4 @@ -;; copyright (c) 2019-2022 Sean Corfield, all rights reserved +;; copyright (c) 2019-2024 Sean Corfield, all rights reserved (ns next.jdbc.sql.builder "Some utility functions for building SQL strings. @@ -20,11 +20,20 @@ ;; characters in table and column names when building SQL: (def ^:private ^:dynamic *allow-suspicious-entities* false) +(defn qualified-name + "Like `clojure.core/name` but preserves the qualifier, if any. + + Intended for use with `:name-fn`, instead of the default `name`." + [k] + (cond-> (str k) + (keyword? k) + (subs 1))) + (defn- safe-name "A wrapper for `name` that throws an exception if the resulting string looks 'suspicious' as a table or column." - [k] - (let [entity (name k) + [k name-fn] + (let [entity (name-fn k) suspicious #";"] (when-not *allow-suspicious-entities* (when (re-find suspicious entity) @@ -48,17 +57,18 @@ as simple aliases, e.g., `[:foo :bar]`, or as expressions with an alias, e.g., `[\"count(*)\" :total]`." [cols opts] - (let [col-fn (:column-fn opts identity)] + (let [col-fn (:column-fn opts identity) + name-fn (:name-fn opts name)] (str/join ", " (map (fn [raw] (if (vector? raw) (if (keyword? (first raw)) - (str (col-fn (safe-name (first raw))) + (str (col-fn (safe-name (first raw) name-fn)) " AS " - (col-fn (safe-name (second raw)))) + (col-fn (safe-name (second raw) name-fn))) (str (first raw) " AS " - (col-fn (safe-name (second raw))))) - (col-fn (safe-name raw)))) + (col-fn (safe-name (second raw) name-fn)))) + (col-fn (safe-name raw name-fn)))) cols)))) @@ -77,15 +87,16 @@ Applies any `:column-fn` supplied in the options." [key-map clause opts] (let [entity-fn (:column-fn opts identity) + name-fn (:name-fn opts name) [where params] (reduce-kv (fn [[conds params] k v] - (let [e (entity-fn (safe-name k))] + (let [e (entity-fn (safe-name k name-fn))] (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 (safe-name clause)) " " + (into [(str (str/upper-case (safe-name clause name-fn)) " " (str/join (if (= :where clause) " AND " ", ") where))] params))) @@ -100,11 +111,12 @@ `DELETE ...` statement." [table where-params opts] (let [entity-fn (:table-fn opts identity) + name-fn (:name-fn opts name) 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 (safe-name table)) + (into [(str "DELETE FROM " (entity-fn (safe-name table name-fn)) " " (first where-params) (when-let [suffix (:suffix opts)] (str " " suffix)))] @@ -120,10 +132,11 @@ `INSERT ...` statement." [table key-map opts] (let [entity-fn (:table-fn opts identity) + name-fn (:name-fn opts name) 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 (safe-name table)) + (into [(str "INSERT INTO " (entity-fn (safe-name table name-fn)) " (" params ")" " VALUES (" places ")" (when-let [suffix (:suffix opts)] @@ -150,10 +163,11 @@ (assert (seq cols) "cols may not be empty") (assert (seq rows) "rows may not be empty") (let [table-fn (:table-fn opts identity) + name-fn (:name-fn opts name) batch? (:batch opts) params (as-cols cols opts) places (as-? (first rows) opts)] - (into [(str "INSERT INTO " (table-fn (safe-name table)) + (into [(str "INSERT INTO " (table-fn (safe-name table name-fn)) " (" params ")" " VALUES " (if batch? @@ -174,12 +188,13 @@ "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)] + (let [entity-fn (:column-fn opts identity) + name-fn (:name-fn opts name)] (cond (keyword? col) - (entity-fn (safe-name col)) + (entity-fn (safe-name col name-fn)) (and (vector? col) (= 2 (count col)) (keyword? (first col))) - (str (entity-fn (safe-name (first col))) + (str (entity-fn (safe-name (first col) name-fn)) " " (or (get {:asc "ASC" :desc "DESC"} (second col)) (throw (IllegalArgumentException. @@ -216,6 +231,7 @@ `SELECT ...` statement." [table where-params opts] (let [entity-fn (:table-fn opts identity) + name-fn (:name-fn opts name) where-params (cond (map? where-params) (by-keys where-params :where opts) (= :all where-params) @@ -236,7 +252,7 @@ (if-let [cols (seq (:columns opts))] (as-cols cols opts) "*") - " FROM " (entity-fn (safe-name table)) + " FROM " (entity-fn (safe-name table name-fn)) (when-let [clause (first where-params)] (str " " clause)) (when-let [order-by (:order-by opts)] @@ -265,12 +281,13 @@ `UPDATE ...` statement." [table key-map where-params opts] (let [entity-fn (:table-fn opts identity) + name-fn (:name-fn opts name) 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 (safe-name table)) + (-> [(str "UPDATE " (entity-fn (safe-name table name-fn)) " " (first set-params) " " (first where-params) (when-let [suffix (:suffix opts)] diff --git a/test/next/jdbc/sql/builder_test.clj b/test/next/jdbc/sql/builder_test.clj index 65c2657..9c6f2ff 100644 --- a/test/next/jdbc/sql/builder_test.clj +++ b/test/next/jdbc/sql/builder_test.clj @@ -11,10 +11,22 @@ (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"]))) + ["WHERE a IS NULL AND b = ? AND c = ?" 42 "s"])) + (is (= (builder/by-keys {:q/a nil :q/b 42 :q/c "s"} :where {}) + ["WHERE a IS NULL AND b = ? AND c = ?" 42 "s"])) + (is (= (builder/by-keys {:q/a nil :q/b 42 :q/c "s"} :where + {:name-fn builder/qualified-name + :column-fn mysql}) + ["WHERE `q/a` IS NULL AND `q/b` = ? AND `q/c` = ?" 42 "s"]))) (testing ":set clause" (is (= (builder/by-keys {:a nil :b 42 :c "s"} :set {}) - ["SET a = ?, b = ?, c = ?" nil 42 "s"])))) + ["SET a = ?, b = ?, c = ?" nil 42 "s"])) + (is (= (builder/by-keys {:q/a nil :q/b 42 :q/c "s"} :set {}) + ["SET a = ?, b = ?, c = ?" nil 42 "s"])) + (is (= (builder/by-keys {:q/a nil :q/b 42 :q/c "s"} :set + {:name-fn builder/qualified-name + :column-fn mysql}) + ["SET `q/a` = ?, `q/b` = ?, `q/c` = ?" nil 42 "s"])))) (deftest test-as-cols (is (= (builder/as-cols [:a :b :c] {}) @@ -22,14 +34,40 @@ (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {}) "a AS aa, b, count(*) AS c")) (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {:column-fn mysql}) - "`a` AS `aa`, `b`, count(*) AS `c`"))) + "`a` AS `aa`, `b`, count(*) AS `c`")) + (is (= (builder/as-cols [:q/a :q/b :q/c] {}) + "a, b, c")) + (is (= (builder/as-cols [[:q/a :q/aa] :q/b ["count(*)" :q/c]] {}) + "a AS aa, b, count(*) AS c")) + (is (= (builder/as-cols [[:q/a :q/aa] :q/b ["count(*)" :q/c]] {:column-fn mysql}) + "`a` AS `aa`, `b`, count(*) AS `c`")) + (is (= (builder/as-cols [:q/a :q/b :q/c] + {:name-fn builder/qualified-name + :column-fn mysql}) + "`q/a`, `q/b`, `q/c`")) + (is (= (builder/as-cols [[:q/a :q/aa] :q/b ["count(*)" :q/c]] + {:name-fn builder/qualified-name + :column-fn mysql}) + "`q/a` AS `q/aa`, `q/b`, count(*) AS `q/c`"))) (deftest test-as-keys (is (= (builder/as-keys {:a nil :b 42 :c "s"} {}) - "a, b, c"))) + "a, b, c")) + (is (= (builder/as-keys {:q/a nil :q/b 42 :q/c "s"} {}) + "a, b, c")) + (is (= (builder/as-keys {:q/a nil :q/b 42 :q/c "s"} + {:name-fn builder/qualified-name + :column-fn sql-server}) + "[q/a], [q/b], [q/c]"))) (deftest test-as-? (is (= (builder/as-? {:a nil :b 42 :c "s"} {}) + "?, ?, ?")) + (is (= (builder/as-? {:q/a nil :q/b 42 :q/c "s"} {}) + "?, ?, ?")) + (is (= (builder/as-? {:q/a nil :q/b 42 :q/c "s"} + {:name-fn builder/qualified-name + :column-fn sql-server}) "?, ?, ?"))) (deftest test-for-query @@ -45,7 +83,35 @@ {:id nil} {:table-fn sql-server :column-fn mysql :suffix "FOR UPDATE"}) - ["SELECT * FROM [user] WHERE `id` IS NULL FOR UPDATE"]))) + ["SELECT * FROM [user] WHERE `id` IS NULL FOR UPDATE"])) + (is (= (builder/for-query + :t/user + {:q/id 9} + {:table-fn sql-server :column-fn mysql :order-by [:x/a [:x/b :desc]]}) + ["SELECT * FROM [user] WHERE `id` = ? ORDER BY `a`, `b` DESC" 9])) + (is (= (builder/for-query :t/user {:q/id nil} {:table-fn sql-server :column-fn mysql}) + ["SELECT * FROM [user] WHERE `id` IS NULL"])) + (is (= (builder/for-query :t/user + {:q/id nil} + {:table-fn sql-server :column-fn mysql + :suffix "FOR UPDATE"}) + ["SELECT * FROM [user] WHERE `id` IS NULL FOR UPDATE"])) + (is (= (builder/for-query + :t/user + {:q/id 9} + {:table-fn sql-server :column-fn mysql :order-by [:x/a [:x/b :desc]] + :name-fn builder/qualified-name}) + ["SELECT * FROM [t/user] WHERE `q/id` = ? ORDER BY `x/a`, `x/b` DESC" 9])) + (is (= (builder/for-query :t/user {:q/id nil} + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["SELECT * FROM [t/user] WHERE `q/id` IS NULL"])) + (is (= (builder/for-query :t/user + {:q/id nil} + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name + :suffix "FOR UPDATE"}) + ["SELECT * FROM [t/user] WHERE `q/id` IS NULL FOR UPDATE"]))) (testing "by where clause" (is (= (builder/for-query :user @@ -112,13 +178,35 @@ :user {:opt nil :id 9} {:table-fn sql-server :column-fn mysql}) - ["DELETE FROM [user] WHERE `opt` IS NULL AND `id` = ?" 9]))) + ["DELETE FROM [user] WHERE `opt` IS NULL AND `id` = ?" 9])) + (is (= (builder/for-delete + :t/user + {:q/opt nil :q/id 9} + {:table-fn sql-server :column-fn mysql}) + ["DELETE FROM [user] WHERE `opt` IS NULL AND `id` = ?" 9])) + (is (= (builder/for-delete + :t/user + {:q/opt nil :q/id 9} + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["DELETE FROM [t/user] WHERE `q/opt` IS NULL AND `q/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])))) + ["DELETE FROM [user] WHERE id = ? and opt is null" 9])) + (is (= (builder/for-delete + :t/user + ["id = ? and opt is null" 9] + {:table-fn sql-server :column-fn mysql}) + ["DELETE FROM [user] WHERE id = ? and opt is null" 9])) + (is (= (builder/for-delete + :t/user + ["id = ? and opt is null" 9] + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["DELETE FROM [t/user] WHERE id = ? and opt is null" 9])))) (deftest test-for-update (testing "empty example (would be a SQL error)" @@ -132,7 +220,18 @@ {:status 42} {:id 9} {:table-fn sql-server :column-fn mysql}) - ["UPDATE [user] SET `status` = ? WHERE `id` = ?" 42 9]))) + ["UPDATE [user] SET `status` = ? WHERE `id` = ?" 42 9])) + (is (= (builder/for-update :t/user + {:q/status 42} + {:q/id 9} + {:table-fn sql-server :column-fn mysql}) + ["UPDATE [user] SET `status` = ? WHERE `id` = ?" 42 9])) + (is (= (builder/for-update :t/user + {:q/status 42} + {:q/id 9} + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["UPDATE [t/user] SET `q/status` = ? WHERE `q/id` = ?" 42 9]))) (testing "by where clause, with nil set value" (is (= (builder/for-update :user {:status 42, :opt nil} @@ -145,7 +244,16 @@ (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]))) + ["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil])) + (is (= (builder/for-insert :t/user + {:q/id 9 :q/status 42 :q/opt nil} + {:table-fn sql-server :column-fn mysql}) + ["INSERT INTO [user] (`id`, `status`, `opt`) VALUES (?, ?, ?)" 9 42 nil])) + (is (= (builder/for-insert :t/user + {:q/id 9 :q/status 42 :q/opt nil} + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["INSERT INTO [t/user] (`q/id`, `q/status`, `q/opt`) VALUES (?, ?, ?)" 9 42 nil]))) (testing "multi-row insert (normal mode)" (is (= (builder/for-insert-multi :user [:id :status] @@ -153,7 +261,22 @@ [35 "world"] [64 "dollars"]] {: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"])) + (is (= (builder/for-insert-multi :t/user + [:q/id :q/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"])) + (is (= (builder/for-insert-multi :t/user + [:q/id :q/status] + [[42 "hello"] + [35 "world"] + [64 "dollars"]] + {:table-fn sql-server :column-fn mysql + :name-fn builder/qualified-name}) + ["INSERT INTO [t/user] (`q/id`, `q/status`) VALUES (?, ?), (?, ?), (?, ?)" 42 "hello" 35 "world" 64 "dollars"]))) (testing "multi-row insert (batch mode)" (is (= (builder/for-insert-multi :user [:id :status] @@ -161,4 +284,19 @@ [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"]])))) + ["INSERT INTO [user] (`id`, `status`) VALUES (?, ?)" [42 "hello"] [35 "world"] [64 "dollars"]])) + (is (= (builder/for-insert-multi :t/user + [:q/id :q/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"]])) + (is (= (builder/for-insert-multi :t/user + [:q/id :q/status] + [[42 "hello"] + [35 "world"] + [64 "dollars"]] + {:table-fn sql-server :column-fn mysql :batch true + :name-fn builder/qualified-name}) + ["INSERT INTO [t/user] (`q/id`, `q/status`) VALUES (?, ?)" [42 "hello"] [35 "world"] [64 "dollars"]]))))