From a1d90a6382fd67942ff131ca2fc72526a752c5fc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 00:14:25 -0700 Subject: [PATCH] Work toward more 1.x compatibility Temporarily disable `AS` in alias while testing compatibility; only quoted by default if `:dialect` specified (may revisit this). --- src/honey/sql.cljc | 131 ++++++++++++----- test/honey/sql_test.cljc | 304 +++++++++++++++++++++++++++++++++++++-- 2 files changed, 392 insertions(+), 43 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index c213418..b86674c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -41,27 +41,75 @@ (str (q t) ".")))) (defn- format-selectable [x] - (if (sequential? x) - (str (let [s (first x)] - (if (map? s) - (format-dsl s) - (format-entity s))) - " AS " - (format-entity (second x))) - (format-entity x))) + (cond (sequential? x) + (str (let [s (first x)] + (if (map? s) + (format-dsl s true) + (format-entity s))) + #_" AS " " " + (format-entity (second x))) + + :else + (format-entity x))) + +(defn- format-selectable-dsl [x] + (cond (map? x) + (format-dsl x true) + + (sequential? x) + (let [s (first x) + [sql & params] (if (map? s) (format-dsl s true) [(format-entity s)])] + (into [(str sql #_" AS " " " (format-entity (second x)))] params)) + + :else + [(format-entity x)])) ;; primary clauses +(defn- format-union [k xs] + (let [[sqls params] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map #'format-dsl xs))] + (into [(str/join (str " " (sql-kw k) " ") sqls)] params))) + (defn- format-selector [k xs] (if (sequential? xs) - [(str (sql-kw k) " " (str/join ", " (map #'format-selectable xs)))] - [(str (sql-kw k) " " (format-selectable xs))])) + (let [[sqls params] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map #'format-selectable-dsl xs))] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) + (let [[sql & params] (format-selectable-dsl xs)] + (into [(str (sql-kw k) " " sql)] params)))) + +(defn- format-insert [k table] + ;; table can be just a table, a pair of table and statement, or a + ;; pair of a pair of table and columns and a statement (yikes!) + (if (sequential? table) + (if (sequential? (first table)) + (let [[[table cols] statement] table + [sql & params] (format-dsl statement)] + (into [(str (sql-kw k) " " (format-selectable table) + " (" + (str/join ", " (map #'format-selectable cols)) + ") " + sql)] + params)) + (let [[table statement] table + [sql & params] (format-dsl statement)] + (into [(str (sql-kw k) " " (format-selectable table) + " " sql)] + params))) + [(str (sql-kw k) " " (format-selectable table))])) (defn- format-join [k [j e]] (let [[sql & params] (format-expr e)] (into [(str (sql-kw k) " " (format-selectable j) " ON " sql)] params))) -(defn- format-where [k e] +(defn- format-on-expr [k e] (let [[sql & params] (format-expr e)] (into [(str (sql-kw k) " " sql)] params))) @@ -86,15 +134,19 @@ (def ^:private clause-order "The (default) order for known clauses. Can have items added and removed." - (atom [:select :from + (atom [:union :union-all + :select :insert-into :update :delete :delete-from :truncate :from :join :left-join :right-join :inner-join :outer-join :full-join - :where :group-by :having :order-by])) + :cross-join + :where :group-by :having :order-by :limit :offset])) (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:select #'format-selector - :insert-into #'format-selector + (atom {:union #'format-union + :union-all #'format-union + :select #'format-selector + :insert-into #'format-insert :update #'format-selector :delete #'format-selector :delete-from #'format-selector @@ -106,17 +158,22 @@ :inner-join #'format-join :outer-join #'format-join :full-join #'format-join - :where #'format-where + :cross-join #'format-selector + :where #'format-on-expr :group-by #'format-group-by - :having #'format-where - :order-by #'format-order-by})) + :having #'format-on-expr + :order-by #'format-order-by + :limit #'format-on-expr + :offset #'format-on-expr})) + +(assert (= (set @clause-order) (set (keys @clause-format)))) (comment :target {:with 20 :with-recursive 30 :intersect 35 - :union 40 - :union-all 45 + ;:union 40 + ;:union-all 45 :except 47 ;:select 50 ;:insert-into 60 @@ -139,23 +196,30 @@ ;:group-by 170 ;:having 180 ;:order-by 190 - :limit 200 - :offset 210 + ;:limit 200 + ;:offset 210 :lock 215 :values 220 :query-values 230}) -(defn- format-dsl [x] - (let [[sqls params] - (reduce (fn [[sql params] k] +(defn- format-dsl [x & [nested?]] + (let [[sqls params leftover] + (reduce (fn [[sql params leftover] k] (if-let [xs (k x)] (let [formatter (k @clause-format) [sql' & params'] (formatter k xs)] - [(conj sql sql') (if params' (into params params') params)]) - [sql params])) - [[] []] + [(conj sql sql') + (if params' (into params params') params) + (dissoc leftover k)]) + [sql params leftover])) + [[] [] x] @clause-order)] - (into [(str/join " " sqls)] params))) + (when (seq leftover) + (throw (ex-info (str "Unknown SQL clauses: " + (str/join ", " (keys leftover))) + leftover))) + (into [(cond-> (str/join " " sqls) + nested? (as-> s (str "(" s ")")))] params))) (def ^:private infix-aliases "Provided for backward compatibility with earlier HoneySQL versions." @@ -193,7 +257,7 @@ (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params)))}) -(defn format-expr [x & nested?] +(defn format-expr [x & [nested?]] (cond (keyword? x) [(format-entity x)] @@ -234,7 +298,9 @@ ([data opts] (let [dialect (get dialects (get opts :dialect :ansi))] (binding [*dialect* dialect - *quoted* (if (contains? opts :quoted) (:quoted opts) true)] + *quoted* (if (contains? opts :quoted) + (:quoted opts) + (contains? opts :dialect))] (format-dsl data))))) (defn set-dialect! @@ -245,13 +311,14 @@ (reset! default-dialect (get dialects dialect :ansi))) (comment + (format {:truncate :foo}) (format-expr [:= :id 1]) (format-expr [:+ :id 1]) (format-expr [:+ 1 [:+ 1 :quux]]) (format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]) (format-expr :id) (format-expr 1) - (format-where :where [:= :id 1]) + (format-on-expr :where [:= :id 1]) (format-dsl {:select [:*] :from [:table] :where [:= :id 1]}) (format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) (format {:select [:*] :from [:table] :group-by [:foo :bar]} {}) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3b16a68..2285d80 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -1,9 +1,10 @@ ;; copyright (c) sean corfield, all rights reserved (ns honey.sql-test + (:refer-clojure :exclude [format]) (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) - [honey.sql :as sut])) + [honey.sql :as sut :refer [format]])) (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] @@ -27,24 +28,305 @@ (#'sut/format-expr [:interval 30 :days])))) (deftest where-test - (#'sut/format-where :where [:= :id 1])) + (is (= ["WHERE id = ?" 1] + (#'sut/format-on-expr :where [:= :id 1])))) (deftest general-tests (is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1] - (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {}))) - (is (= ["SELECT \"t\".* FROM \"table\" AS \"t\" WHERE \"id\" = ?" 1] - (#'sut/format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}))) + (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:quoted true}))) + ;; temporarily remove AS from alias here + (is (= ["SELECT \"t\".* FROM \"table\" \"t\" WHERE \"id\" = ?" 1] + (#'sut/format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" GROUP BY \"foo\", \"bar\""] - (#'sut/format {:select [:*] :from [:table] :group-by [:foo :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :group-by [:foo :bar]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" GROUP BY DATE(\"bar\")"] - (#'sut/format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}))) + (#'sut/format {:select [:*] :from [:table] :group-by [[:date :bar]]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" ORDER BY \"foo\" DESC, \"bar\" ASC"] - (#'sut/format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" ORDER BY DATE(\"expiry\") DESC, \"bar\" ASC"] - (#'sut/format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" WHERE DATE_ADD(\"expiry\", INTERVAL ? DAYS) < NOW()" 30] - (#'sut/format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}))) + (#'sut/format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {:quoted true}))) (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}))) (is (= ["SELECT * FROM \"table\" WHERE \"id\" IN (?,?,?,?)" 1 2 3 4] - (#'sut/format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {})))) + (#'sut/format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {:quoted true})))) + +;; tests lifted from HoneySQL v1 to check for compatibility + + +(deftest alias-splitting + (is (= ["SELECT `aa`.`c` AS `a.c`, `bb`.`c` AS `b.c`, `cc`.`c` AS `c.c`"] + (format {:select [[:aa.c "a.c"] + [:bb.c :b.c] + [:cc.c 'c.c]]} + {:dialect :mysql})) + "aliases containing \".\" are quoted as necessary but not split")) + +(deftest values-alias + (is (= ["SELECT vals.a FROM (VALUES (?, ?, ?)) vals (a, b, c)" 1 2 3] + (format {:select [:vals.a] + :from [[{:values [[1 2 3]]} [:vals {:columns [:a :b :c]}]]]})))) +(deftest test-cte + (is (= (format {:with [[:query {:select [:foo] :from [:bar]}]]}) + ["WITH query AS SELECT foo FROM bar"])) + (is (= (format {:with-recursive [[:query {:select [:foo] :from [:bar]}]]}) + ["WITH RECURSIVE query AS SELECT foo FROM bar"])) + (is (= (format {:with [[[:static {:columns [:a :b :c]}] {:values [[1 2 3] [4 5 6]]}]]}) + ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, ?))" 1 2 3 4 5 6])) + (is (= (format + {:with [[[:static {:columns [:a :b :c]}] + {:values [[1 2 3] [4 5 6]]}]] + :select [:*] + :from [:static]}) + ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, ?)) SELECT * FROM static" 1 2 3 4 5 6]))) + +(deftest insert-into + (is (= (format {:insert-into :foo}) + ["INSERT INTO foo"])) + (is (= (format {:insert-into [:foo {:select [:bar] :from [:baz]}]}) + ["INSERT INTO foo SELECT bar FROM baz"])) + (is (= (format {:insert-into [[:foo [:a :b :c]] {:select [:d :e :f] :from [:baz]}]}) + ["INSERT INTO foo (a, b, c) SELECT d, e, f FROM baz"])) + (is (= (format {:insert-into [[:foo [:a :b :c]] {:select [:d :e :f] :from [:baz]}]}) + ["INSERT INTO foo (a, b, c) SELECT d, e, f FROM baz"]))) + +(deftest insert-into-namespaced + ;; un-namespaced: works as expected: + (is (= (format {:insert-into :foo :values [{:foo/id 1}]}) + ["INSERT INTO foo (id) VALUES (?)" 1])) + (is (= (format {:insert-into :foo :columns [:foo/id] :values [[2]]}) + ["INSERT INTO foo (id) VALUES (?)" 2])) + (is (= (format {:insert-into :foo :values [{:foo/id 1}]} + {:namespace-as-table? true}) + ["INSERT INTO foo (id) VALUES (?)" 1])) + (is (= (format {:insert-into :foo :columns [:foo/id] :values [[2]]} + {:namespace-as-table? true}) + ["INSERT INTO foo (id) VALUES (?)" 2]))) + +(deftest exists-test + (is (= (format {:exists {:select [:a] :from [:foo]}}) + ["EXISTS (SELECT a FROM foo)"])) + (is (= (format {:select [:id] + :from [:foo] + :where [:exists {:select [1] + :from [:bar] + :where :deleted}]}) + ["SELECT id FROM foo WHERE EXISTS (SELECT ? FROM bar WHERE deleted)" 1]))) + +(deftest array-test + (println 'sql-array :unimplemented) + #_(is (= (format {:insert-into :foo + :columns [:baz] + :values [[(sql/array [1 2 3 4])]]}) + ["INSERT INTO foo (baz) VALUES (ARRAY[?, ?, ?, ?])" 1 2 3 4])) + (println 'sql-array :unimplemented) + #_(is (= (format {:insert-into :foo + :columns [:baz] + :values [[(sql/array ["one" "two" "three"])]]}) + ["INSERT INTO foo (baz) VALUES (ARRAY[?, ?, ?])" "one" "two" "three"]))) + +(deftest union-test + ;; UNION and INTERSECT subexpressions should not be parenthesized. + ;; If you need to add more complex expressions, use a subquery like this: + ;; SELECT foo FROM bar1 + ;; UNION + ;; SELECT foo FROM (SELECT foo FROM bar2 ORDER BY baz LIMIT 2) + ;; ORDER BY foo ASC + (is (= (format {:union [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}]}) + ["SELECT foo FROM bar1 UNION SELECT foo FROM bar2"]))) + +(deftest union-all-test + (is (= (format {:union-all [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}]}) + ["SELECT foo FROM bar1 UNION ALL SELECT foo FROM bar2"]))) + +(deftest intersect-test + (is (= (format {:intersect [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}]}) + ["SELECT foo FROM bar1 INTERSECT SELECT foo FROM bar2"]))) + +(deftest except-test + (is (= (format {:except [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}]}) + ["SELECT foo FROM bar1 EXCEPT SELECT foo FROM bar2"]))) + +(deftest inner-parts-test + (testing "The correct way to apply ORDER BY to various parts of a UNION" + (is (= (format + {:union + [{:select [:amount :id :created_on] + :from [:transactions]} + {:select [:amount :id :created_on] + :from [{:select [:amount :id :created_on] + :from [:other_transactions] + :order-by [[:amount :desc]] + :limit 5}]}] + :order-by [[:amount :asc]]}) + ["SELECT amount, id, created_on FROM transactions UNION SELECT amount, id, created_on FROM (SELECT amount, id, created_on FROM other_transactions ORDER BY amount DESC LIMIT ?) ORDER BY amount ASC" 5])))) + +(deftest compare-expressions-test + (testing "Sequences should be fns when in value/comparison spots" + (is (= ["SELECT foo FROM bar WHERE (col1 mod ?) = (col2 + ?)" 4 4] + (format {:select [:foo] + :from [:bar] + :where [:= [:mod :col1 4] [:+ :col2 4]]})))) + + (testing "Value context only applies to sequences in value/comparison spots" + (let [sub {:select [:%sum.amount] + :from [:bar] + :where [:in :id ["id-1" "id-2"]]}] + (is (= ["SELECT total FROM foo WHERE (SELECT sum(amount) FROM bar WHERE (id in (?, ?))) = total" "id-1" "id-2"] + (format {:select [:total] + :from [:foo] + :where [:= sub :total]}))) + (is (= ["WITH t AS (SELECT sum(amount) FROM bar WHERE (id in (?, ?))) SELECT total FROM foo WHERE total = t" "id-1" "id-2"] + (format {:with [[:t sub]] + :select [:total] + :from [:foo] + :where [:= :total :t]})))))) + +(deftest union-with-cte + (is (= (format {:union [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}] + :with [[[:bar {:columns [:spam :eggs]}] + {:values [[1 2] [3 4] [5 6]]}]]}) + ["WITH bar (spam, eggs) AS (VALUES (?, ?), (?, ?), (?, ?)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2" 1 2 3 4 5 6]))) + + +(deftest union-all-with-cte + (is (= (format {:union-all [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}] + :with [[[:bar {:columns [:spam :eggs]}] + {:values [[1 2] [3 4] [5 6]]}]]}) + ["WITH bar (spam, eggs) AS (VALUES (?, ?), (?, ?), (?, ?)) SELECT foo FROM bar1 UNION ALL SELECT foo FROM bar2" 1 2 3 4 5 6]))) + +(deftest parameterizer-none + (testing "array parameter" + (println 'sql-array :unimplemented) + #_(is (= (format {:insert-into :foo + :columns [:baz] + :values [[(sql/array [1 2 3 4])]]} + {:parameterizer :none}) + ["INSERT INTO foo (baz) VALUES (ARRAY[1, 2, 3, 4])"]))) + + (testing "union complex values" + (is (= (format {:union [{:select [:foo] :from [:bar1]} + {:select [:foo] :from [:bar2]}] + :with [[[:bar {:columns [:spam :eggs]}] + {:values [[1 2] [3 4] [5 6]]}]]} + {:parameterizer :none}) + ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2"])))) + +(deftest where-and + (testing "should ignore a nil predicate" + (is (= (format {:where [:and [:= :foo "foo"] [:= :bar "bar"] nil]} + {:parameterizer :postgresql}) + ["WHERE (foo = $1 AND bar = $2)" "foo" "bar"])))) + + +#_(defmethod parameterize :single-quote [_ value pname] (str \' value \')) +#_(defmethod parameterize :mysql-fill [_ value pname] "?") + +(deftest customized-parameterizer + (testing "should fill param with single quote" + (is (= (format {:where [:and [:= :foo "foo"] [:= :bar "bar"] nil]} + {:parameterizer :single-quote}) + ["WHERE (foo = 'foo' AND bar = 'bar')" "foo" "bar"]))) + (testing "should fill param with ?" + (is (= (format {:where [:and [:= :foo "foo"] [:= :bar "bar"] nil]} + {:parameterizer :mysql-fill}) + ["WHERE (foo = ? AND bar = ?)" "foo" "bar"])))) + + +(deftest set-before-from ; issue 235 + (is (= + ["UPDATE `films` `f` SET `kind` = `c`.`test` FROM (SELECT `b`.`test` FROM `bar` `b` WHERE `b`.`id` = ?) `c` WHERE `f`.`kind` = ?" 1 "drama"] + (-> + {:update [:films :f] + :set0 {:kind :c.test} + :from [[{:select [:b.test] + :from [[:bar :b]] + :where [:= :b.id 1]} :c]] + :where [:= :f.kind "drama"]} + (format {:dialect :mysql}))))) + +(deftest set-after-join + (is (= + ["UPDATE `foo` INNER JOIN `bar` ON `bar`.`id` = `foo`.`bar_id` SET `a` = ? WHERE `bar`.`b` = ?" 1 42] + (-> + {:update :foo + :join [:bar [:= :bar.id :foo.bar_id]] + :set {:a 1} + :where [:= :bar.b 42]} + (format {:dialect :mysql})))) + (is (= + ["UPDATE `foo` INNER JOIN `bar` ON `bar`.`id` = `foo`.`bar_id` SET `a` = ? WHERE `bar`.`b` = ?" 1 42] + (-> + {:update :foo + :join [:bar [:= :bar.id :foo.bar_id]] + :set1 {:a 1} + :where [:= :bar.b 42]} + (format {:dialect :mysql}))))) + +(deftest delete-from-test + (is (= ["DELETE FROM `foo` WHERE `foo`.`id` = ?" 42] + (-> {:delete-from :foo + :where [:= :foo.id 42]} + (format {:dialect :mysql}))))) + +(deftest delete-test + (is (= ["DELETE `t1`, `t2` FROM `table1` `t1` INNER JOIN `table2` `t2` ON `t1`.`fk` = `t2`.`id` WHERE `t1`.`bar` = ?" 42] + (-> {:delete [:t1 :t2] + :from [[:table1 :t1]] + :join [[:table2 :t2] [:= :t1.fk :t2.id]] + :where [:= :t1.bar 42]} + (format {:dialect :mysql}))))) + +(deftest truncate-test + (is (= ["TRUNCATE `foo`"] + (-> {:truncate :foo} + (format {:dialect :mysql}))))) + +(deftest inlined-values-are-stringified-correctly + (println 'inline :unimplemented) + #_(is (= ["SELECT foo, bar, NULL"] + (format {:select [(honeysql.core/inline "foo") + (honeysql.core/inline :bar) + (honeysql.core/inline nil)]})))) + +;; Make sure if Locale is Turkish we're not generating queries like İNNER JOIN (dot over the I) because +;; `string/upper-case` is converting things to upper-case using the default Locale. Generated query should be the same +;; regardless of system Locale. See #236 +#?(:clj + (deftest statements-generated-correctly-with-turkish-locale + (let [format-with-locale (fn [^String language-tag] + (let [original-locale (java.util.Locale/getDefault)] + (try + (java.util.Locale/setDefault (java.util.Locale/forLanguageTag language-tag)) + (format {:select [:t2.name] + :from [[:table1 :t1]] + :join [[:table2 :t2] [:= :t1.fk :t2.id]] + :where [:= :t1.id 1]}) + (finally + (java.util.Locale/setDefault original-locale)))))] + (is (= (format-with-locale "en") + (format-with-locale "tr")))))) + +(deftest join-on-true-253 + ;; used to work on honeysql 0.9.2; broke in 0.9.3 + (is (= ["SELECT foo FROM bar INNER JOIN table t ON TRUE"] + (format {:select [:foo] + :from [:bar] + :join [[:table :t] true]})))) + +(deftest cross-join-test + (is (= ["SELECT * FROM foo CROSS JOIN bar"] + (format {:select [:*] + :from [:foo] + :cross-join [:bar]}))) + (is (= ["SELECT * FROM foo f CROSS JOIN bar b"] + (format {:select [:*] + :from [[:foo :f]] + :cross-join [[:bar :b]]}))))