From 29b6e47a8e7a00a8711b9d032f1323ea2f38db0e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 20 Sep 2020 18:48:07 -0700 Subject: [PATCH 001/254] Experimental WIP --- src/honey/specs.clj | 13 +++ src/honey/sql.cljc | 205 ++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 218 insertions(+) create mode 100644 src/honey/specs.clj create mode 100644 src/honey/sql.cljc diff --git a/src/honey/specs.clj b/src/honey/specs.clj new file mode 100644 index 0000000..cb2d631 --- /dev/null +++ b/src/honey/specs.clj @@ -0,0 +1,13 @@ +;; copyright (c) 2020 sean corfield, all rights reserved + +(ns honey.specs + "Optional namespace containing `clojure.spec` representations of + the data format used as the underlying DSL for HoneySQL." + (:require [clojure.spec.alpha :as s])) + +(s/def ::sql-expression any?) + +(s/def ::dsl (s/map-of simple-keyword? + (s/coll-of ::sql-expression + :kind vector? + :min-count 1))) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc new file mode 100644 index 0000000..aacf4da --- /dev/null +++ b/src/honey/sql.cljc @@ -0,0 +1,205 @@ +;; copyright (c) 2020 sean corfield, all rights reserved + +(ns honey.sql + "Primary API for HoneySQL 2.x." + (:refer-clojure :exclude [format]) + (:require [clojure.string :as str])) + +;; default formatting for known clauses + +(declare format-dsl) +(declare format-expr) + +;; dynamic dialect handling for formatting + +(def ^:private dialects + {:ansi {:quote #(str \" % \")} + :mssql {:quote #(str \[ % \])} + :mysql {:quote #(str \` % \`)}}) + +; should become defonce +(def ^:private default-dialect (atom (:ansi dialects))) + +(def ^:private ^:dynamic *dialect* nil) +(def ^:private ^:dynamic *quoted* nil) + +;; clause helpers + +(defn- sql-kw [k] + (-> k (name) (str/upper-case) (str/replace "-" " "))) + +(defn- format-entity [x] + (let [q (if *quoted* (:quote *dialect*) identity) + [t c] (if-let [n (namespace x)] + [n (name x)] + (let [[t c] (str/split (name x) #"\.")] + (if c [t c] [nil t])))] + (cond->> c + (not= "*" c) + (q) + t + (str (q t) ".")))) + +(defn- format-selectable [x] + (if (vector? x) + (str (let [s (first x)] + (if (map? s) + (format-dsl s) + (format-entity s))) + " AS " + (format-entity (second x))) + (format-entity x))) + +;; primary clauses + +(defn- format-selector [k xs] + [(str (sql-kw k) " " (str/join ", " (map #'format-selectable xs)))]) + +(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] + (let [[sql & params] (format-expr e)] + (into [(str (sql-kw k) " " sql)] params))) + +(defn- format-expr-list [xs] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map #'format-expr xs))) + +(defn- format-group-by [k xs] + (let [[sqls params] (format-expr-list xs)] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) + +(defn- format-order-by [k xs] + (let [dirs (map #(if (vector? %) (second %) :asc) xs) + [sqls params] (format-expr-list (map #(if (vector? %) (first %) %) xs))] + (into [(str (sql-kw k) " " + (str/join ", " (map (fn [sql dir] (str sql " " (sql-kw dir))) + sqls + dirs)))] params))) + +(def ^:private clause-order + "The (default) order for known clauses. Can have items added and removed." + (atom [:select :from :join :where :group-by :order-by])) + +(def ^:private clause-format + "The (default) behavior for each known clause. Can also have items added + and removed." + (atom {:select #'format-selector + :from #'format-selector + :join #'format-join ; any join works + :where #'format-where + :group-by #'format-group-by + :order-by #'format-order-by})) + +(defn- format-dsl [x] + (let [[sqls params] + (reduce (fn [[sql params] 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])) + [[] []] + @clause-order)] + (into [(str/join " " sqls)] params))) + +(def ^:private infix-aliases + "Provided for backward compatibility with earlier HoneySQL versions." + {:is := + :is-not :<> + :not= :<> + :!= :<> + :regex :regexp}) + +(def ^:private infix-ops + (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" + "in" "not-in" "like" "not-like" "regexp" + "is" "is-not" "not=" "!=" "regex"} + (into (map str "+-*/%|&^=<>")) + (into (keys infix-aliases)) + (into (vals infix-aliases)) + (->> (into #{} (map keyword))))) + +(def ^:private special-syntax + {:cast + (fn [[x type]] + (let [[sql & params] (format-expr x)] + (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) + :interval + (fn [[n units]] + (let [[sql & params] (format-expr n)] + (into [(str "INTERVAL " sql " " (sql-kw units))] params)))}) + +(defn format-expr [x & nested?] + (cond (keyword? x) + [(format-entity x)] + + (vector? x) + (let [op (first x)] + (if (keyword? op) + (cond (infix-ops op) + (let [[_ a b] x + [s1 & p1] (format-expr a true) + [s2 & p2] (format-expr b true)] + (-> (str s1 " " + (sql-kw (get infix-aliases op op)) + " " s2) + (cond-> nested? + (as-> s (str "(" s ")"))) + (vector) + (into p1) + (into p2))) + (special-syntax op) + (let [formatter (special-syntax op)] + (formatter (rest x))) + :else + (let [[sqls params] (format-expr-list (rest x))] + (into [(str (sql-kw op) + "(" (str/join ", " sqls) ")")] + params))) + (into [(str "(" (str/join "," + (repeat (count x) "?")) ")")] + x))) + + :else + ["?" x])) + +(defn Hformat + "Turn the data DSL into a vector containing a SQL string followed by + any parameter values that were encountered in the DSL structure." + ([data] (Hformat data {})) + ([data opts] + (let [dialect (get dialects (get opts :dialect :ansi))] + (binding [*dialect* dialect + *quoted* (if (contains? opts :quoted) (:quoted opts) true)] + (format-dsl data))))) + +(defn set-dialect! + "Set the default dialect for formatting. + + Can be: `:ansi` (the default), `:mssql`, `:mysql`." + [dialect] + (reset! default-dialect (get dialects dialect :ansi))) + +(comment + (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-dsl {:select [:*] :from [:table] :where [:= :id 1]}) + (Hformat {:select [:t.*] :from [[:table :t]] :where [:= :id 1]}) + (Hformat {:select [:*] :from [:table] :group-by [:foo :bar]}) + (Hformat {:select [:*] :from [:table] :group-by [[:date :bar]]}) + (Hformat {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]}) + (Hformat {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]}) + (Hformat {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]}) + (format-expr [:interval 30 :days]) + (Hformat {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + ,) From 2c98d35f63d11df57db505091604477ada9e84c1 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 20 Sep 2020 19:17:37 -0700 Subject: [PATCH 002/254] Start some tests; implement more clauses --- src/honey/sql.cljc | 105 +++++++++++++++++++++++++++++++-------- test/honey/sql_test.cljc | 11 ++++ 2 files changed, 94 insertions(+), 22 deletions(-) create mode 100644 test/honey/sql_test.cljc diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index aacf4da..80c039f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -41,7 +41,7 @@ (str (q t) ".")))) (defn- format-selectable [x] - (if (vector? x) + (if (sequential? x) (str (let [s (first x)] (if (map? s) (format-dsl s) @@ -53,7 +53,9 @@ ;; primary clauses (defn- format-selector [k xs] - [(str (sql-kw k) " " (str/join ", " (map #'format-selectable xs)))]) + (if (sequential? xs) + [(str (sql-kw k) " " (str/join ", " (map #'format-selectable xs)))] + [(str (sql-kw k) " " (format-selectable xs))])) (defn- format-join [k [j e]] (let [[sql & params] (format-expr e)] @@ -74,8 +76,9 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-order-by [k xs] - (let [dirs (map #(if (vector? %) (second %) :asc) xs) - [sqls params] (format-expr-list (map #(if (vector? %) (first %) %) xs))] + (let [dirs (map #(if (sequential? %) (second %) :asc) xs) + [sqls params] + (format-expr-list (map #(if (sequential? %) (first %) %) xs))] (into [(str (sql-kw k) " " (str/join ", " (map (fn [sql dir] (str sql " " (sql-kw dir))) sqls @@ -83,17 +86,64 @@ (def ^:private clause-order "The (default) order for known clauses. Can have items added and removed." - (atom [:select :from :join :where :group-by :order-by])) + (atom [:select :from + :join :left-join :right-join :inner-join :outer-join :full-join + :where :group-by :having :order-by])) (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:select #'format-selector - :from #'format-selector - :join #'format-join ; any join works - :where #'format-where - :group-by #'format-group-by - :order-by #'format-order-by})) + (atom {:select #'format-selector + :insert-into #'format-selector + :update #'format-selector + :delete #'format-selector + :delete-from #'format-selector + :truncate #'format-selector + :from #'format-selector + :join #'format-join + :left-join #'format-join + :right-join #'format-join + :inner-join #'format-join + :outer-join #'format-join + :full-join #'format-join + :where #'format-where + :group-by #'format-group-by + :having #'format-where + :order-by #'format-order-by})) + +(comment :target + {:with 20 + :with-recursive 30 + :intersect 35 + :union 40 + :union-all 45 + :except 47 + ;:select 50 + ;:insert-into 60 + ;:update 70 + ;:delete 75 + ;:delete-from 80 + ;:truncate 85 + :columns 90 + :composite 95 + :set0 100 ; low-priority set clause + ;:from 110 + ;:join 120 + ;:left-join 130 + ;:right-join 140 + ;:full-join 150 + :cross-join 152 ; doesn't have on clauses + :set 155 + :set1 156 ; high-priority set clause (synonym for :set) + ;:where 160 + ;:group-by 170 + ;:having 180 + ;:order-by 190 + :limit 200 + :offset 210 + :lock 215 + :values 220 + :query-values 230}) (defn- format-dsl [x] (let [[sqls params] @@ -125,7 +175,16 @@ (->> (into #{} (map keyword))))) (def ^:private special-syntax - {:cast + {:between + (fn [[x a b]] + (let [[sql-x & params-x] (format-expr x true) + [sql-a & params-a] (format-expr a true) + [sql-b & params-b] (format-expr b true)] + (-> [(str sql-x " BETWEEN " sql-a " AND " sql-b)] + (into params-x) + (into params-a) + (into params-b)))) + :cast (fn [[x type]] (let [[sql & params] (format-expr x)] (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) @@ -138,7 +197,7 @@ (cond (keyword? x) [(format-entity x)] - (vector? x) + (sequential? x) (let [op (first x)] (if (keyword? op) (cond (infix-ops op) @@ -168,10 +227,10 @@ :else ["?" x])) -(defn Hformat +(defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." - ([data] (Hformat data {})) + ([data] (format data {})) ([data opts] (let [dialect (get dialects (get opts :dialect :ansi))] (binding [*dialect* dialect @@ -186,6 +245,7 @@ (reset! default-dialect (get dialects dialect :ansi))) (comment + format (format-expr [:= :id 1]) (format-expr [:+ :id 1]) (format-expr [:+ 1 [:+ 1 :quux]]) @@ -194,12 +254,13 @@ (format-expr 1) (format-where :where [:= :id 1]) (format-dsl {:select [:*] :from [:table] :where [:= :id 1]}) - (Hformat {:select [:t.*] :from [[:table :t]] :where [:= :id 1]}) - (Hformat {:select [:*] :from [:table] :group-by [:foo :bar]}) - (Hformat {:select [:*] :from [:table] :group-by [[:date :bar]]}) - (Hformat {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]}) - (Hformat {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]}) - (Hformat {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]}) + (format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]}) + (format {:select [:*] :from [:table] :group-by [:foo :bar]}) + (format {:select [:*] :from [:table] :group-by [[:date :bar]]}) + (format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]}) + (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]}) + (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]}) (format-expr [:interval 30 :days]) - (Hformat {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]}) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc new file mode 100644 index 0000000..d33f0da --- /dev/null +++ b/test/honey/sql_test.cljc @@ -0,0 +1,11 @@ +;; copyright (c) sean corfield, all rights reserved + +(ns honey.sql-test + (:require #?(:clj [clojure.test :refer [deftest is testing]] + :cljs [cljs.test :refer-macros [deftest is testing]]) + [honey.sql :as sut])) + +(deftest mysql-tests + (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] + (sut/format {:select [:*] :from [:table] :where [:= :id 1]} + {:dialect :mysql})))) From b6d6d2c4f41e2237aa27cc610002c71176db413c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 20 Sep 2020 21:33:04 -0700 Subject: [PATCH 003/254] Refactor to sql-format for now --- src/honey/sql.cljc | 32 ++++++++++++++++++-------------- test/honey/sql_test.cljc | 4 ++-- 2 files changed, 20 insertions(+), 16 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 80c039f..84a45e6 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -227,15 +227,19 @@ :else ["?" x])) +(defn- sql-format + "Format the data into SQL + params according to the options." + [data opts] + (let [dialect (get dialects (get opts :dialect :ansi))] + (binding [*dialect* dialect + *quoted* (if (contains? opts :quoted) (:quoted opts) true)] + (format-dsl data)))) + (defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." - ([data] (format data {})) - ([data opts] - (let [dialect (get dialects (get opts :dialect :ansi))] - (binding [*dialect* dialect - *quoted* (if (contains? opts :quoted) (:quoted opts) true)] - (format-dsl data))))) + ([data] (sql-format data {})) + ([data opts] (sql-format data opts))) (defn set-dialect! "Set the default dialect for formatting. @@ -254,13 +258,13 @@ (format-expr 1) (format-where :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]}) - (format {:select [:*] :from [:table] :group-by [[:date :bar]]}) - (format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]}) - (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]}) - (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]}) + (sql-format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) + (sql-format {:select [:*] :from [:table] :group-by [:foo :bar]} {}) + (sql-format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}) + (sql-format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}) + (sql-format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) + (sql-format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) - (format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) - (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]}) + (sql-format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (sql-format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {}) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index d33f0da..ba50ab0 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -7,5 +7,5 @@ (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] - (sut/format {:select [:*] :from [:table] :where [:= :id 1]} - {:dialect :mysql})))) + (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} + {:dialect :mysql})))) From 1dc0447244a6b55213a7dcf245f94f03398d68b3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 20 Sep 2020 22:25:28 -0700 Subject: [PATCH 004/254] Convert more RCFs to tests --- src/honey/sql.cljc | 1 - test/honey/sql_test.cljc | 39 +++++++++++++++++++++++++++++++++++++++ 2 files changed, 39 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 84a45e6..5fa997e 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -249,7 +249,6 @@ (reset! default-dialect (get dialects dialect :ansi))) (comment - format (format-expr [:= :id 1]) (format-expr [:+ :id 1]) (format-expr [:+ 1 [:+ 1 :quux]]) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index ba50ab0..8c0f0f8 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -9,3 +9,42 @@ (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql})))) + +(deftest expr-tests + (is (= ["id = ?" 1] + (#'sut/format-expr [:= :id 1]))) + (is (= ["id + ?" 1] + (#'sut/format-expr [:+ :id 1]))) + (is (= ["? + (? + quux)" 1 1] + (#'sut/format-expr [:+ 1 [:+ 1 :quux]]))) + (is (= ["FOO(BAR(? + G(abc)), F(?, quux))" 2 1] + (#'sut/format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]))) + (is (= ["id"] + (#'sut/format-expr :id))) + (is (= ["?" 1] + (#'sut/format-expr 1))) + (is (= ["INTERVAL ? DAYS" 30] + (#'sut/format-expr [:interval 30 :days])))) + +(deftest where-test + (#'sut/format-where :where [:= :id 1])) + +(deftest general-tests + (is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1] + (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} {}))) + (is (= ["SELECT \"t\".* FROM \"table\" AS \"t\" WHERE \"id\" = ?" 1] + (#'sut/sql-format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}))) + (is (= ["SELECT * FROM \"table\" GROUP BY \"foo\", \"bar\""] + (#'sut/sql-format {:select [:*] :from [:table] :group-by [:foo :bar]} {}))) + (is (= ["SELECT * FROM \"table\" GROUP BY DATE(\"bar\")"] + (#'sut/sql-format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}))) + (is (= ["SELECT * FROM \"table\" ORDER BY \"foo\" DESC, \"bar\" ASC"] + (#'sut/sql-format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}))) + (is (= ["SELECT * FROM \"table\" ORDER BY DATE(\"expiry\") DESC, \"bar\" ASC"] + (#'sut/sql-format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}))) + (is (= ["SELECT * FROM \"table\" WHERE DATE_ADD(\"expiry\", INTERVAL ? DAYS) < NOW()" 30] + (#'sut/sql-format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}))) + (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] + (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}))) + (is (= ["SELECT * FROM \"table\" WHERE \"id\" IN (?,?,?,?)" 1 2 3 4] + (#'sut/sql-format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {})))) From 834ac3a096a1addece3fc71d885e3ce5a761fcfd Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 21 Sep 2020 10:56:05 -0700 Subject: [PATCH 005/254] Rename sql-format back to format now Chlorine is updated! --- src/honey/sql.cljc | 32 ++++++++++++++------------------ test/honey/sql_test.cljc | 20 ++++++++++---------- 2 files changed, 24 insertions(+), 28 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5fa997e..c213418 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -227,19 +227,15 @@ :else ["?" x])) -(defn- sql-format - "Format the data into SQL + params according to the options." - [data opts] - (let [dialect (get dialects (get opts :dialect :ansi))] - (binding [*dialect* dialect - *quoted* (if (contains? opts :quoted) (:quoted opts) true)] - (format-dsl data)))) - (defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." - ([data] (sql-format data {})) - ([data opts] (sql-format data opts))) + ([data] (format data {})) + ([data opts] + (let [dialect (get dialects (get opts :dialect :ansi))] + (binding [*dialect* dialect + *quoted* (if (contains? opts :quoted) (:quoted opts) true)] + (format-dsl data))))) (defn set-dialect! "Set the default dialect for formatting. @@ -257,13 +253,13 @@ (format-expr 1) (format-where :where [:= :id 1]) (format-dsl {:select [:*] :from [:table] :where [:= :id 1]}) - (sql-format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) - (sql-format {:select [:*] :from [:table] :group-by [:foo :bar]} {}) - (sql-format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}) - (sql-format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}) - (sql-format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) - (sql-format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) + (format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) + (format {:select [:*] :from [:table] :group-by [:foo :bar]} {}) + (format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}) + (format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}) + (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) + (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) - (sql-format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) - (sql-format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {}) + (format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {}) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 8c0f0f8..3b16a68 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -7,7 +7,7 @@ (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] - (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} + (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql})))) (deftest expr-tests @@ -31,20 +31,20 @@ (deftest general-tests (is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1] - (#'sut/sql-format {: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/sql-format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}))) + (#'sut/format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}))) (is (= ["SELECT * FROM \"table\" GROUP BY \"foo\", \"bar\""] - (#'sut/sql-format {:select [:*] :from [:table] :group-by [:foo :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :group-by [:foo :bar]} {}))) (is (= ["SELECT * FROM \"table\" GROUP BY DATE(\"bar\")"] - (#'sut/sql-format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}))) + (#'sut/format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}))) (is (= ["SELECT * FROM \"table\" ORDER BY \"foo\" DESC, \"bar\" ASC"] - (#'sut/sql-format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}))) (is (= ["SELECT * FROM \"table\" ORDER BY DATE(\"expiry\") DESC, \"bar\" ASC"] - (#'sut/sql-format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}))) + (#'sut/format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}))) (is (= ["SELECT * FROM \"table\" WHERE DATE_ADD(\"expiry\", INTERVAL ? DAYS) < NOW()" 30] - (#'sut/sql-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]]} {}))) (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] - (#'sut/sql-format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}))) + (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}))) (is (= ["SELECT * FROM \"table\" WHERE \"id\" IN (?,?,?,?)" 1 2 3 4] - (#'sut/sql-format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {})))) + (#'sut/format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {})))) From a1d90a6382fd67942ff131ca2fc72526a752c5fc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 00:14:25 -0700 Subject: [PATCH 006/254] 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]]})))) From 1a699f18ab7fd2cd853416c50328d26679279ad2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 12:55:02 -0700 Subject: [PATCH 007/254] Support more clauses; flesh out dialect and clause ordering --- src/honey/sql.cljc | 162 +++++++++++++++++++++++++++++++-------- test/honey/sql_test.cljc | 14 +--- 2 files changed, 134 insertions(+), 42 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b86674c..965977f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -12,21 +12,65 @@ ;; dynamic dialect handling for formatting +(def ^:private default-clause-order + "The (default) order for known clauses. Can have items added and removed." + [:intersect :union :union-all :except + :select :insert-into :update :delete :delete-from :truncate + :columns :set :from + :join :left-join :right-join :inner-join :outer-join :full-join + :cross-join + :where :group-by :having :order-by :limit :offset :values]) + +(defn- add-clause-before + "Low-level helper just to insert a new clause." + [order clause before] + (if before + (do + (when-not (contains? (set order) before) + (throw (ex-info (str "Unrecognized clause: " before) + {:known-clauses order}))) + (reduce (fn [v k] + (if (= k before) + (conj v clause k) + (conj v k))) + [] + order)) + (conj order clause))) + (def ^:private dialects {:ansi {:quote #(str \" % \")} :mssql {:quote #(str \[ % \])} - :mysql {:quote #(str \` % \`)}}) + :mysql {:quote #(str \` % \`) + :clause-order-fn #(add-clause-before + (filterv (complement #{:set}) %) + :set + :where)}}) ; should become defonce (def ^:private default-dialect (atom (:ansi dialects))) (def ^:private ^:dynamic *dialect* nil) +(def ^:private ^:dynamic *clause-order* nil) (def ^:private ^:dynamic *quoted* nil) ;; clause helpers +;; String.toUpperCase() or `str/upper-case` for that matter converts the +;; string to uppercase for the DEFAULT LOCALE. Normally this does what you'd +;; expect but things like `inner join` get converted to `İNNER JOİN` (dot over +;; the I) when user locale is Turkish. This predictably has bad consequences +;; for people who like their SQL queries to work. The fix here is to use +;; String.toUpperCase(Locale/US) instead which always converts things the +;; way we'd expect. +;; +;; Use this instead of `str/upper-case` as it will always use Locale/US. +(def ^:private ^{:arglists '([s])} upper-case + ;; TODO - not sure if there's a JavaScript equivalent here we should be using as well + #?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US)))) + :cljs str/upper-case)) + (defn- sql-kw [k] - (-> k (name) (str/upper-case) (str/replace "-" " "))) + (-> k (name) (upper-case) (str/replace "-" " "))) (defn- format-entity [x] (let [q (if *quoted* (:quote *dialect*) identity) @@ -61,12 +105,15 @@ [sql & params] (if (map? s) (format-dsl s true) [(format-entity s)])] (into [(str sql #_" AS " " " (format-entity (second x)))] params)) + (keyword? x) + [(format-entity x)] + :else - [(format-entity x)])) + (format-expr x))) ;; primary clauses -(defn- format-union [k xs] +(defn- format-on-set-op [k xs] (let [[sqls params] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) @@ -107,7 +154,11 @@ (defn- format-join [k [j e]] (let [[sql & params] (format-expr e)] - (into [(str (sql-kw k) " " (format-selectable j) " ON " sql)] params))) + ;; for backward compatibility, treat plain JOIN as INNER JOIN: + (into [(str (sql-kw (if (= :join k) :inner-join k)) " " + (format-selectable j) " ON " + sql)] + params))) (defn- format-on-expr [k e] (let [[sql & params] (format-expr e)] @@ -132,25 +183,43 @@ sqls dirs)))] params))) -(def ^:private clause-order - "The (default) order for known clauses. Can have items added and removed." - (atom [:union :union-all - :select :insert-into :update :delete :delete-from :truncate :from - :join :left-join :right-join :inner-join :outer-join :full-join - :cross-join - :where :group-by :having :order-by :limit :offset])) +(defn- format-values [k xs] + (if (sequential? (first xs)) + ;; [[1 2 3] [4 5 6]] + (let [[sqls params] + (reduce (fn [[sql params] [sqls' params']] + [(conj sql (str "(" (str/join ", " sqls') ")")) + (into params params')]) + [[] []] + (map #'format-expr-list xs))] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) + ;; [1 2 3] + (let [[sqls params] (format-expr-list xs)] + (into [(str (sql-kw k) " (" (str/join ", " sqls) ")")] params)))) + +(defn- format-set-exprs [k xs] + ;; TODO: !!! + ["SET a = ?, b = ?" 42 13]) + +(def ^:private current-clause-order + "The (current) order for known clauses. Can have items added and removed." + (atom default-clause-order)) (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:union #'format-union - :union-all #'format-union + (atom {:intersect #'format-on-set-op + :union #'format-on-set-op + :union-all #'format-on-set-op + :except #'format-on-set-op :select #'format-selector :insert-into #'format-insert :update #'format-selector :delete #'format-selector :delete-from #'format-selector :truncate #'format-selector + :columns #'format-selector + :set #'format-set-exprs :from #'format-selector :join #'format-join :left-join #'format-join @@ -164,24 +233,25 @@ :having #'format-on-expr :order-by #'format-order-by :limit #'format-on-expr - :offset #'format-on-expr})) + :offset #'format-on-expr + :values #'format-values})) -(assert (= (set @clause-order) (set (keys @clause-format)))) +(assert (= (set @current-clause-order) (set (keys @clause-format)))) (comment :target {:with 20 :with-recursive 30 - :intersect 35 + ;:intersect 35 ;:union 40 ;:union-all 45 - :except 47 + ;:except 47 ;:select 50 ;:insert-into 60 ;:update 70 ;:delete 75 ;:delete-from 80 ;:truncate 85 - :columns 90 + ;:columns 90 :composite 95 :set0 100 ; low-priority set clause ;:from 110 @@ -189,7 +259,7 @@ ;:left-join 130 ;:right-join 140 ;:full-join 150 - :cross-join 152 ; doesn't have on clauses + ;:cross-join 152 ; doesn't have on clauses :set 155 :set1 156 ; high-priority set clause (synonym for :set) ;:where 160 @@ -213,13 +283,18 @@ (dissoc leftover k)]) [sql params leftover])) [[] [] x] - @clause-order)] - (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))) + *clause-order*)] + (if (seq leftover) + (do + ;; TODO: for testing purposes, make this less noisy + (println (str "\n-------------------\nUnknown SQL clauses: " + (str/join ", " (keys leftover)))) + #_(throw (ex-info (str "Unknown SQL clauses: " + (str/join ", " (keys leftover))) + leftover)) + [(str "")]) + (into [(cond-> (str/join " " sqls) + nested? (as-> s (str "(" s ")")))] params)))) (def ^:private infix-aliases "Provided for backward compatibility with earlier HoneySQL versions." @@ -261,6 +336,9 @@ (cond (keyword? x) [(format-entity x)] + (map? x) + (format-dsl x true) + (sequential? x) (let [op (first x)] (if (keyword? op) @@ -291,16 +369,28 @@ :else ["?" x])) +(defn- check-dialect [dialect] + (when-not (contains? dialects dialect) + (throw (ex-info (str "Invalid dialect: " dialect) + {:valid-dialects (vec (sort (keys dialects)))}))) + dialect) + (defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." ([data] (format data {})) ([data opts] - (let [dialect (get dialects (get opts :dialect :ansi))] - (binding [*dialect* dialect + (let [dialect? (contains? opts :dialect) + dialect (when dialect? (get dialects (check-dialect (:dialect opts))))] + (binding [*dialect* (if dialect? dialect @default-dialect) + *clause-order* (if dialect? + (if-let [f (:clause-order-fn dialect)] + (f @current-clause-order) + @current-clause-order) + @current-clause-order) *quoted* (if (contains? opts :quoted) (:quoted opts) - (contains? opts :dialect))] + dialect?)] (format-dsl data))))) (defn set-dialect! @@ -308,7 +398,17 @@ Can be: `:ansi` (the default), `:mssql`, `:mysql`." [dialect] - (reset! default-dialect (get dialects dialect :ansi))) + (reset! default-dialect (get dialects (check-dialect dialect))) + (when-let [f (:clause-order-fn @default-dialect)] + (swap! current-clause-order f))) + +(defn register-clause! + "Register a new clause formatter. If `before` is `nil`, the clause is + added to the end of the list of known clauses, otherwise it is inserted + immediately prior to that clause." + [clause formatter before] + (swap! current-clause-order add-clause-before clause before) + (swap! clause-format assoc clause formatter)) (comment (format {:truncate :foo}) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 2285d80..d45bbf6 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -242,15 +242,15 @@ (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\" 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} + :set {:kind :c.test} :from [[{:select [:b.test] :from [[:bar :b]] :where [:= :b.id 1]} :c]] :where [:= :f.kind "drama"]} - (format {:dialect :mysql}))))) + (format))))) (deftest set-after-join (is (= @@ -260,14 +260,6 @@ :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 From f7d5e3a4cf0526a22611085c09319229200fdd03 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 18:15:20 -0700 Subject: [PATCH 008/254] Down to just 8 failures now! Mising: array, inline, parameterizer. --- src/honey/sql.cljc | 240 +++++++++++++++++++++++++++------------ test/honey/sql_test.cljc | 58 ++++++---- 2 files changed, 203 insertions(+), 95 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 965977f..9940e15 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -9,12 +9,13 @@ (declare format-dsl) (declare format-expr) +(declare format-expr-list) ;; dynamic dialect handling for formatting (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." - [:intersect :union :union-all :except + [:with :with-recursive :intersect :union :union-all :except :select :insert-into :update :delete :delete-from :truncate :columns :set :from :join :left-join :right-join :inner-join :outer-join :full-join @@ -50,7 +51,9 @@ (def ^:private default-dialect (atom (:ansi dialects))) (def ^:private ^:dynamic *dialect* nil) -(def ^:private ^:dynamic *clause-order* nil) +;; nil would be a better default but that makes testing individual +;; functions harder than necessary: +(def ^:private ^:dynamic *clause-order* default-clause-order) (def ^:private ^:dynamic *quoted* nil) ;; clause helpers @@ -72,41 +75,66 @@ (defn- sql-kw [k] (-> k (name) (upper-case) (str/replace "-" " "))) -(defn- format-entity [x] - (let [q (if *quoted* (:quote *dialect*) identity) - [t c] (if-let [n (namespace x)] - [n (name x)] - (let [[t c] (str/split (name x) #"\.")] - (if c [t c] [nil t])))] +(defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] + (let [q (if *quoted* (:quote *dialect*) identity) + call (fn [f x] (str f "(" x ")")) + [f t c] (if-let [n (when-not (or drop-ns? (string? x)) + (namespace x))] + [nil n (name x)] + (let [[t c] (if aliased? + [(name x)] + (str/split (name x) #"\."))] + ;; I really dislike like %func.arg shorthand syntax! + (cond (= \% (first t)) + [(subs t 1) nil c] + c + [nil t c] + :else + [nil nil t])))] (cond->> c (not= "*" c) (q) t - (str (q t) ".")))) + (str (q t) ".") + f + (call f)))) -(defn- format-selectable [x] +(defn- format-entity-alias [x] (cond (sequential? x) (str (let [s (first x)] (if (map? s) - (format-dsl s true) + (throw (ex-info "selectable cannot be statement!" + {:selectable s})) (format-entity s))) #_" AS " " " - (format-entity (second x))) + (format-entity (second x) {:aliased? true})) :else (format-entity x))) -(defn- format-selectable-dsl [x] +(defn- format-selectable-dsl [x & [{:keys [as? aliased?] :as opts}]] (cond (map? x) - (format-dsl x true) + (format-dsl x {:nested? 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)) + a (second x) + [sql & params] (if (map? s) + (format-dsl s {:nested? true}) + (format-expr s)) + [sql' & params'] (if (sequential? a) + (let [[sql params] (format-expr-list a {:aliased? true})] + (into [(str/join " " sql)] params)) + (format-selectable-dsl a {:aliased? true}))] + (-> [(str sql (if as? " AS " " ") sql')] + (into params) + (into params'))) - (keyword? x) - [(format-entity x)] + (or (keyword? x) (symbol? x)) + [(format-entity x opts)] + + (and aliased? (string? x)) + [(format-entity x opts)] :else (format-expr x))) @@ -121,17 +149,55 @@ (map #'format-dsl xs))] (into [(str/join (str " " (sql-kw k) " ") sqls)] params))) -(defn- format-selector [k xs] +(defn- format-expr-list [xs & [opts]] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map #(format-expr % opts) xs))) + +(defn- format-columns [_ xs] + (let [[sqls params] (format-expr-list xs {:drop-ns? true})] + (into [(str "(" (str/join ", " sqls) ")")] params))) + +(defn- format-selects [k xs] (if (sequential? xs) (let [[sqls params] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #'format-selectable-dsl xs))] + (map #(format-selectable-dsl % {:as? (= k :select)}) xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) - (let [[sql & params] (format-selectable-dsl xs)] + (let [[sql & params] (format-selectable-dsl xs {:as? (= k :select)})] (into [(str (sql-kw k) " " sql)] params)))) +(defn- format-with-part [x] + (if (sequential? x) + (let [[sql & params] (format-dsl (second x))] + (into [(str (format-entity (first x)) " " sql)] params)) + [(format-entity x)])) + +(defn- format-with [k xs] + ;; TODO: a sequence of pairs -- X AS expr -- where X is either [entity expr] + ;; or just entity, as far as I can tell... + (let [[sqls params] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map (fn [[x expr]] + (let [[sql & params] (format-with-part x) + [sql' & params'] (format-dsl expr)] + (cond-> [(str sql " AS " + (if (seq params') + (str "(" sql' ")") + sql'))] + params (into params) + params' (into params')))) + xs))] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) + +(defn- format-selector [k xs] + (format-selects k [xs])) + (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!) @@ -139,24 +205,24 @@ (if (sequential? (first table)) (let [[[table cols] statement] table [sql & params] (format-dsl statement)] - (into [(str (sql-kw k) " " (format-selectable table) + (into [(str (sql-kw k) " " (format-entity-alias table) " (" - (str/join ", " (map #'format-selectable cols)) + (str/join ", " (map #'format-entity-alias cols)) ") " sql)] params)) (let [[table statement] table [sql & params] (format-dsl statement)] - (into [(str (sql-kw k) " " (format-selectable table) + (into [(str (sql-kw k) " " (format-entity-alias table) " " sql)] params))) - [(str (sql-kw k) " " (format-selectable table))])) + [(str (sql-kw k) " " (format-entity-alias table))])) (defn- format-join [k [j e]] (let [[sql & params] (format-expr e)] ;; for backward compatibility, treat plain JOIN as INNER JOIN: (into [(str (sql-kw (if (= :join k) :inner-join k)) " " - (format-selectable j) " ON " + (format-entity-alias j) " ON " sql)] params))) @@ -164,12 +230,6 @@ (let [[sql & params] (format-expr e)] (into [(str (sql-kw k) " " sql)] params))) -(defn- format-expr-list [xs] - (reduce (fn [[sql params] [sql' & params']] - [(conj sql sql') (if params' (into params params') params)]) - [[] []] - (map #'format-expr xs))) - (defn- format-group-by [k xs] (let [[sqls params] (format-expr-list xs)] (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) @@ -184,22 +244,47 @@ dirs)))] params))) (defn- format-values [k xs] - (if (sequential? (first xs)) - ;; [[1 2 3] [4 5 6]] - (let [[sqls params] - (reduce (fn [[sql params] [sqls' params']] - [(conj sql (str "(" (str/join ", " sqls') ")")) - (into params params')]) - [[] []] - (map #'format-expr-list xs))] - (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) - ;; [1 2 3] - (let [[sqls params] (format-expr-list xs)] - (into [(str (sql-kw k) " (" (str/join ", " sqls) ")")] params)))) + (cond (sequential? (first xs)) + ;; [[1 2 3] [4 5 6]] + (let [[sqls params] + (reduce (fn [[sql params] [sqls' params']] + [(conj sql (str "(" (str/join ", " sqls') ")")) + (into params params')]) + [[] []] + (map #'format-expr-list xs))] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) + + (map? (first xs)) + ;; [{:a 1 :b 2 :c 3}] + (let [cols (keys (first xs)) + [sqls params] + (reduce (fn [[sql params] [sqls' params']] + [(conj sql (str/join ", " sqls')) + (if params' (into params params') params')]) + [[] []] + (map (fn [m] + (format-expr-list (map #(get m %) cols))) + xs))] + (into [(str "(" + (str/join ", " + (map #(format-entity % {:drop-ns? true}) cols)) + ") " + (sql-kw k) " (" (str/join ", " sqls) ")")] + params)) + + :else + (throw (ex-info ":values expects sequences or maps" + {:first (first xs)})))) (defn- format-set-exprs [k xs] - ;; TODO: !!! - ["SET a = ?, b = ?" 42 13]) + (let [[sqls params] + (reduce-kv (fn [[sql params] v e] + (let [[sql' & params'] (format-expr e)] + [(conj sql (str (format-entity v) " = " sql')) + (if params' (into params params') params)])) + [[] []] + xs)] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (def ^:private current-clause-order "The (current) order for known clauses. Can have items added and removed." @@ -208,26 +293,28 @@ (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:intersect #'format-on-set-op + (atom {:with #'format-with + :with-recursive #'format-with + :intersect #'format-on-set-op :union #'format-on-set-op :union-all #'format-on-set-op :except #'format-on-set-op - :select #'format-selector + :select #'format-selects :insert-into #'format-insert :update #'format-selector - :delete #'format-selector + :delete #'format-selects :delete-from #'format-selector :truncate #'format-selector - :columns #'format-selector + :columns #'format-columns :set #'format-set-exprs - :from #'format-selector + :from #'format-selects :join #'format-join :left-join #'format-join :right-join #'format-join :inner-join #'format-join :outer-join #'format-join :full-join #'format-join - :cross-join #'format-selector + :cross-join #'format-selects :where #'format-on-expr :group-by #'format-group-by :having #'format-on-expr @@ -239,8 +326,8 @@ (assert (= (set @current-clause-order) (set (keys @clause-format)))) (comment :target - {:with 20 - :with-recursive 30 + {;:with 20 + ;:with-recursive 30 ;:intersect 35 ;:union 40 ;:union-all 45 @@ -253,15 +340,15 @@ ;:truncate 85 ;:columns 90 :composite 95 - :set0 100 ; low-priority set clause + ;; no longer needed/supported :set0 100 ; low-priority set clause ;:from 110 ;:join 120 ;:left-join 130 ;:right-join 140 ;:full-join 150 ;:cross-join 152 ; doesn't have on clauses - :set 155 - :set1 156 ; high-priority set clause (synonym for :set) + ;:set 155 + ;; no longer needed/supported :set1 156 ; high-priority set clause (synonym for :set) ;:where 160 ;:group-by 170 ;:having 180 @@ -269,10 +356,10 @@ ;:limit 200 ;:offset 210 :lock 215 - :values 220 + ;:values 220 :query-values 230}) -(defn- format-dsl [x & [nested?]] +(defn- format-dsl [x & [{:keys [aliased? nested?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] (if-let [xs (k x)] @@ -294,7 +381,8 @@ leftover)) [(str "")]) (into [(cond-> (str/join " " sqls) - nested? (as-> s (str "(" s ")")))] params)))) + (and nested? (not aliased?)) + (as-> s (str "(" s ")")))] params)))) (def ^:private infix-aliases "Provided for backward compatibility with earlier HoneySQL versions." @@ -316,9 +404,9 @@ (def ^:private special-syntax {:between (fn [[x a b]] - (let [[sql-x & params-x] (format-expr x true) - [sql-a & params-a] (format-expr a true) - [sql-b & params-b] (format-expr b true)] + (let [[sql-x & params-x] (format-expr x {:nested? true}) + [sql-a & params-a] (format-expr a {:nested? true}) + [sql-b & params-b] (format-expr b {:nested? true})] (-> [(str sql-x " BETWEEN " sql-a " AND " sql-b)] (into params-x) (into params-a) @@ -332,20 +420,20 @@ (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params)))}) -(defn format-expr [x & [nested?]] - (cond (keyword? x) - [(format-entity x)] +(defn format-expr [x & [{:keys [nested?] :as opts}]] + (cond (or (keyword? x) (symbol? x)) + [(format-entity x opts)] (map? x) - (format-dsl x true) + (format-dsl x (assoc opts :nested? true)) (sequential? x) (let [op (first x)] (if (keyword? op) (cond (infix-ops op) (let [[_ a b] x - [s1 & p1] (format-expr a true) - [s2 & p2] (format-expr b true)] + [s1 & p1] (format-expr a {:nested? true}) + [s2 & p2] (format-expr b {:nested? true})] (-> (str s1 " " (sql-kw (get infix-aliases op op)) " " s2) @@ -358,14 +446,22 @@ (let [formatter (special-syntax op)] (formatter (rest x))) :else - (let [[sqls params] (format-expr-list (rest x))] + (let [args (rest x) + [sqls params] (format-expr-list args)] (into [(str (sql-kw op) - "(" (str/join ", " sqls) ")")] + (if (and (= 1 (count args)) + (map? (first args)) + (= 1 (count sqls))) + (str " " (first sqls)) + (str "(" (str/join ", " sqls) ")")))] params))) - (into [(str "(" (str/join "," + (into [(str "(" (str/join ", " (repeat (count x) "?")) ")")] x))) + (boolean? x) + [(upper-case (str x))] + :else ["?" x])) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index d45bbf6..33ef52c 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -8,8 +8,8 @@ (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] - (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} - {:dialect :mysql})))) + (sut/format {:select [:*] :from [:table] :where [:= :id 1]} + {:dialect :mysql})))) (deftest expr-tests (is (= ["id = ?" 1] @@ -33,24 +33,24 @@ (deftest general-tests (is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1] - (#'sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:quoted true}))) + (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}))) + (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]} {:quoted true}))) + (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]]} {:quoted true}))) + (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]} {:quoted true}))) + (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]} {:quoted true}))) + (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]]} {:quoted true}))) + (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]]} {:quoted true})))) + (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]]} {:quoted true})))) ;; tests lifted from HoneySQL v1 to check for compatibility @@ -105,8 +105,12 @@ ["INSERT INTO foo (id) VALUES (?)" 2]))) (deftest exists-test - (is (= (format {:exists {:select [:a] :from [:foo]}}) - ["EXISTS (SELECT a FROM foo)"])) + ;; EXISTS should never have been implemented as SQL syntax: it's an operator! + #_(is (= (format {:exists {:select [:a] :from [:foo]}}) + ["EXISTS (SELECT a FROM foo)"])) + ;; ugly because it's hard to select just a function call without an alias: + (is (= (format {:select [[[:exists {:select [:a] :from [:foo]}] :x]]}) + ["SELECT EXISTS (SELECT a FROM foo) AS x"])) (is (= (format {:select [:id] :from [:foo] :where [:exists {:select [1] @@ -115,12 +119,12 @@ ["SELECT id FROM foo WHERE EXISTS (SELECT ? FROM bar WHERE deleted)" 1]))) (deftest array-test - (println 'sql-array :unimplemented) + (is nil "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 nil "sql-array unimplemented") #_(is (= (format {:insert-into :foo :columns [:baz] :values [[(sql/array ["one" "two" "three"])]]}) @@ -135,7 +139,15 @@ ;; ORDER BY foo ASC (is (= (format {:union [{:select [:foo] :from [:bar1]} {:select [:foo] :from [:bar2]}]}) - ["SELECT foo FROM bar1 UNION SELECT foo FROM bar2"]))) + ["SELECT foo FROM bar1 UNION SELECT foo FROM bar2"])) + + (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]]}]]}) + ["WITH bar (spam, eggs) AS (VALUES (?, ?), (?, ?), (?, ?)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2" + 1 2 3 4 5 6])))) (deftest union-all-test (is (= (format {:union-all [{:select [:foo] :from [:bar1]} @@ -168,7 +180,7 @@ (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] + (is (= ["SELECT foo FROM bar WHERE (col1 MOD ?) = (col2 + ?)" 4 4] (format {:select [:foo] :from [:bar] :where [:= [:mod :col1 4] [:+ :col2 4]]})))) @@ -177,11 +189,11 @@ (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"] + (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"] + (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] @@ -204,7 +216,7 @@ (deftest parameterizer-none (testing "array parameter" - (println 'sql-array :unimplemented) + (is nil "sql-array unimplemented") #_(is (= (format {:insert-into :foo :columns [:baz] :values [[(sql/array [1 2 3 4])]]} @@ -250,7 +262,7 @@ :from [[:bar :b]] :where [:= :b.id 1]} :c]] :where [:= :f.kind "drama"]} - (format))))) + (format {:quoted true}))))) (deftest set-after-join (is (= @@ -282,7 +294,7 @@ (format {:dialect :mysql}))))) (deftest inlined-values-are-stringified-correctly - (println 'inline :unimplemented) + (is nil "inline unimplemented") #_(is (= ["SELECT foo, bar, NULL"] (format {:select [(honeysql.core/inline "foo") (honeysql.core/inline :bar) From 4408a6e7d2d58253188d1eb890a4ff5ed9444afd Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 20:25:38 -0700 Subject: [PATCH 009/254] Update test runner to latest CLI --- run-tests.sh | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/run-tests.sh b/run-tests.sh index 884c2a0..9f5e209 100755 --- a/run-tests.sh +++ b/run-tests.sh @@ -1,8 +1,8 @@ #!/bin/sh -echo ==== Test README.md ==== && clojure -A:readme && \ - echo ==== Lint Source ==== && clojure -A:eastwood && \ - echo ==== Test ClojureScript ==== && clojure -A:test:cljs-runner +echo ==== Test README.md ==== && clojure -M:readme && \ + echo ==== Lint Source ==== && clojure -M:eastwood && \ + echo ==== Test ClojureScript ==== && clojure -M:test:cljs-runner if test $? -eq 0 then @@ -11,7 +11,7 @@ then for v in 1.7 1.8 1.9 1.10 master do echo ==== Test Clojure $v ==== - clojure -A:test:runner:$v + clojure -M:test:runner:$v if test $? -ne 0 then exit 1 @@ -19,7 +19,7 @@ then done else echo ==== Test Clojure ==== - clojure -A:test:runner + clojure -M:test:runner fi else exit 1 From 97531fa4cf046d8242234a2075a1e277f81e93f0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 22:25:13 -0700 Subject: [PATCH 010/254] Implement array as SQL syntax instead of special HoneySQL syntax --- src/honey/sql.cljc | 6 +++++- test/honey/sql_test.cljc | 43 +++++++++++++++++++--------------------- 2 files changed, 25 insertions(+), 24 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 9940e15..9cfcb66 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -402,7 +402,11 @@ (->> (into #{} (map keyword))))) (def ^:private special-syntax - {:between + {:array + (fn [[arr]] + (let [[sqls params] (format-expr-list arr)] + (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) + :between (fn [[x a b]] (let [[sql-x & params-x] (format-expr x {:nested? true}) [sql-a & params-a] (format-expr a {:nested? true}) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 33ef52c..ce0f1d2 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -13,19 +13,19 @@ (deftest expr-tests (is (= ["id = ?" 1] - (#'sut/format-expr [:= :id 1]))) + (sut/format-expr [:= :id 1]))) (is (= ["id + ?" 1] - (#'sut/format-expr [:+ :id 1]))) + (sut/format-expr [:+ :id 1]))) (is (= ["? + (? + quux)" 1 1] - (#'sut/format-expr [:+ 1 [:+ 1 :quux]]))) + (sut/format-expr [:+ 1 [:+ 1 :quux]]))) (is (= ["FOO(BAR(? + G(abc)), F(?, quux))" 2 1] - (#'sut/format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]))) + (sut/format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]))) (is (= ["id"] - (#'sut/format-expr :id))) + (sut/format-expr :id))) (is (= ["?" 1] - (#'sut/format-expr 1))) + (sut/format-expr 1))) (is (= ["INTERVAL ? DAYS" 30] - (#'sut/format-expr [:interval 30 :days])))) + (sut/format-expr [:interval 30 :days])))) (deftest where-test (is (= ["WHERE id = ?" 1] @@ -119,16 +119,14 @@ ["SELECT id FROM foo WHERE EXISTS (SELECT ? FROM bar WHERE deleted)" 1]))) (deftest array-test - (is nil "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])) - (is nil "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"]))) + (is (= (format {:insert-into :foo + :columns [:baz] + :values [[[:array [1 2 3 4]]]]}) + ["INSERT INTO foo (baz) VALUES (ARRAY[?, ?, ?, ?])" 1 2 3 4])) + (is (= (format {:insert-into :foo + :columns [:baz] + :values [[[:array ["one" "two" "three"]]]]}) + ["INSERT INTO foo (baz) VALUES (ARRAY[?, ?, ?])" "one" "two" "three"]))) (deftest union-test ;; UNION and INTERSECT subexpressions should not be parenthesized. @@ -216,12 +214,11 @@ (deftest parameterizer-none (testing "array parameter" - (is nil "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])"]))) + (is (= (format {:insert-into :foo + :columns [:baz] + :values [[[: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]} From 3ce47b92f2acb391d0af9108c4a5609d5422b394 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 23 Sep 2020 22:52:57 -0700 Subject: [PATCH 011/254] Implement :inline syntax; allow select call without alias --- src/honey/sql.cljc | 45 +++++++++++++++++++++++++++------------- test/honey/sql_test.cljc | 9 ++++---- 2 files changed, 35 insertions(+), 19 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 9cfcb66..8d12e5c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -101,13 +101,15 @@ (defn- format-entity-alias [x] (cond (sequential? x) - (str (let [s (first x)] - (if (map? s) - (throw (ex-info "selectable cannot be statement!" - {:selectable s})) - (format-entity s))) - #_" AS " " " - (format-entity (second x) {:aliased? true})) + (let [s (first x) + pair? (< 1 (count x))] + (when (map? s) + (throw (ex-info "selectable cannot be statement!" + {:selectable s}))) + (cond-> (format-entity s) + pair? + (str #_" AS " " " + (format-entity (second x) {:aliased? true})))) :else (format-entity x))) @@ -117,16 +119,20 @@ (format-dsl x {:nested? true}) (sequential? x) - (let [s (first x) - a (second x) + (let [s (first x) + pair? (< 1 (count x)) + a (second x) [sql & params] (if (map? s) (format-dsl s {:nested? true}) (format-expr s)) - [sql' & params'] (if (sequential? a) - (let [[sql params] (format-expr-list a {:aliased? true})] - (into [(str/join " " sql)] params)) - (format-selectable-dsl a {:aliased? true}))] - (-> [(str sql (if as? " AS " " ") sql')] + [sql' & params'] (when pair? + (if (sequential? a) + (let [[sql params] (format-expr-list a {:aliased? true})] + (into [(str/join " " sql)] params)) + (format-selectable-dsl a {:aliased? true})))] + (-> [(cond-> sql + pair? + (str (if as? " AS " " ") sql'))] (into params) (into params'))) @@ -401,6 +407,14 @@ (into (vals infix-aliases)) (->> (into #{} (map keyword))))) +(defn- sqlize-value [x] + (cond + (nil? x) "NULL" + (string? x) x ; I feel this should be 'single-quoted' but 1.x does not + (symbol? x) (name x) + (keyword? x) (name x) + :else (str x))) + (def ^:private special-syntax {:array (fn [[arr]] @@ -419,6 +433,9 @@ (fn [[x type]] (let [[sql & params] (format-expr x)] (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) + :inline + (fn [[x]] + [(sqlize-value x)]) :interval (fn [[n units]] (let [[sql & params] (format-expr n)] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index ce0f1d2..3f290e3 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -291,11 +291,10 @@ (format {:dialect :mysql}))))) (deftest inlined-values-are-stringified-correctly - (is nil "inline unimplemented") - #_(is (= ["SELECT foo, bar, NULL"] - (format {:select [(honeysql.core/inline "foo") - (honeysql.core/inline :bar) - (honeysql.core/inline nil)]})))) + (is (= ["SELECT foo, bar, NULL"] + (format {:select [[[:inline "foo"]] + [[:inline :bar]] + [[: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 From ba701b60cd57ca13bafd46b46f8ec3815dacd3a0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 24 Sep 2020 11:04:18 -0700 Subject: [PATCH 012/254] Continue to support Clojure 1.7 for now --- src/honey/sql.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 8d12e5c..f55293c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -480,7 +480,7 @@ (repeat (count x) "?")) ")")] x))) - (boolean? x) + (or (true? x) (false? x)) ; because (boolean? x) requires Clojure 1.9+ [(upper-case (str x))] :else From 6cf8fa9e456bb8aafbc939ba187ab670b0500687 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 24 Sep 2020 11:13:08 -0700 Subject: [PATCH 013/254] Implement base clause order for more predictable dialect selection --- src/honey/sql.cljc | 33 +++++++++++++++++++++++++++------ 1 file changed, 27 insertions(+), 6 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f55293c..4bedf59 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -292,8 +292,16 @@ xs)] (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) +(def ^:private base-clause-order + "The (base) order for known clauses. Can have items added and removed. + + This is the 'pre-dialect' ordering." + (atom default-clause-order)) + (def ^:private current-clause-order - "The (current) order for known clauses. Can have items added and removed." + "The (current) order for known clauses. Can have items added and removed. + + This is the 'post-dialect` ordering when a new default dialect is set." (atom default-clause-order)) (def ^:private clause-format @@ -329,7 +337,9 @@ :offset #'format-on-expr :values #'format-values})) -(assert (= (set @current-clause-order) (set (keys @clause-format)))) +(assert (= (set @base-clause-order) + (set @current-clause-order) + (set (keys @clause-format)))) (comment :target {;:with 20 @@ -502,7 +512,7 @@ (binding [*dialect* (if dialect? dialect @default-dialect) *clause-order* (if dialect? (if-let [f (:clause-order-fn dialect)] - (f @current-clause-order) + (f @base-clause-order) @current-clause-order) @current-clause-order) *quoted* (if (contains? opts :quoted) @@ -513,17 +523,28 @@ (defn set-dialect! "Set the default dialect for formatting. - Can be: `:ansi` (the default), `:mssql`, `:mysql`." + Can be: `:ansi` (the default), `:mssql`, `:mysql`. + + Dialects are always applied to the base order to create the current order." [dialect] (reset! default-dialect (get dialects (check-dialect dialect))) (when-let [f (:clause-order-fn @default-dialect)] - (swap! current-clause-order f))) + (reset! current-clause-order (f @base-clause-order)))) (defn register-clause! "Register a new clause formatter. If `before` is `nil`, the clause is added to the end of the list of known clauses, otherwise it is inserted - immediately prior to that clause." + immediately prior to that clause. + + New clauses are registered in the base order and the current order so + that any dialect selections are able to include them while still working + predictably from the base order. Caveat: that means if you are a new + clause `before` a clause that is ordered differently in different + dialects, your new clause may also end up in a different place. The + only clause so far where that would matter is `:set` which differs in + MySQL..." [clause formatter before] + (swap! base-clause-order add-clause-before clause before) (swap! current-clause-order add-clause-before clause before) (swap! clause-format assoc clause formatter)) From 11ef895c4a23a5e58a7a2a276beee1a75dd2aae8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 24 Sep 2020 19:07:32 -0700 Subject: [PATCH 014/254] Clean up dialect support; start docs Also move old namespaces to test-only tree for reference while I continue developing V2. --- README.md | 24 +- doc/cljdoc.edn | 11 + doc/differences-from-1-x.md | 106 +++++ doc/getting-started.md | 3 + src/honey/sql.cljc | 30 +- src/honey/sql/helpers.clj | 6 + src/readme.clj | 593 ++++++++++++++++++++++++++++ test/honey/sql_test.cljc | 5 +- {src => test}/honeysql/core.cljc | 0 {src => test}/honeysql/format.cljc | 0 {src => test}/honeysql/helpers.cljc | 0 {src => test}/honeysql/types.cljc | 0 {src => test}/honeysql/util.clj | 0 13 files changed, 756 insertions(+), 22 deletions(-) create mode 100644 doc/cljdoc.edn create mode 100644 doc/differences-from-1-x.md create mode 100644 doc/getting-started.md create mode 100644 src/honey/sql/helpers.clj create mode 100644 src/readme.clj rename {src => test}/honeysql/core.cljc (100%) rename {src => test}/honeysql/format.cljc (100%) rename {src => test}/honeysql/helpers.cljc (100%) rename {src => test}/honeysql/types.cljc (100%) rename {src => test}/honeysql/util.clj (100%) diff --git a/README.md b/README.md index c4ed4db..b1d0e3f 100644 --- a/README.md +++ b/README.md @@ -1,15 +1,17 @@ -# Honey SQL [![CircleCI](https://circleci.com/gh/seancorfield/honeysql/tree/develop.svg?style=svg)](https://circleci.com/gh/seancorfield/honeysql/tree/develop) +# Honey SQL [![CircleCI](https://circleci.com/gh/seancorfield/honeysql/tree/v2.svg?style=svg)](https://circleci.com/gh/seancorfield/honeysql/tree/v2) SQL as Clojure data structures. Build queries programmatically -- even at runtime -- without having to bash strings together. ## Build -The latest versions on Clojars and on cljdoc: +The latest stable version (1.0.444) on Clojars and on cljdoc: [![Clojars Project](https://clojars.org/honeysql/latest-version.svg)](https://clojars.org/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.444)](https://cljdoc.org/d/honeysql/honeysql/CURRENT) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. +This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). + ## Note on code samples All sample code in this README is automatically run as a unit test using @@ -17,14 +19,14 @@ All sample code in this README is automatically run as a unit test using Note that while some of these samples show pretty-printed SQL, this is just for README readability; honeysql does not generate pretty-printed SQL. -The `#sql/regularize` directive tells the test-runner to ignore the extraneous -whitespace. + +_The `#sql/regularize` directive tells the test-runner to ignore the extraneous whitespace._ [TODO: replace with pretty print option!] ## Usage ```clojure -(require '[honeysql.core :as sql] - '[honeysql.helpers :refer :all :as helpers]) +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer :all :as helpers]) ``` Everything is built on top of maps representing SQL queries: @@ -46,6 +48,8 @@ Column names can be provided as keywords or symbols (but not strings -- HoneySQL => ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] ``` +_The handling of namespace-qualified keywords is under review in 2.x._ + By default, namespace-qualified keywords are treated as simple keywords: their namespace portion is ignored. This was the behavior in HoneySQL prior to the 0.9.0 release and has been restored since the 0.9.7 release as this is considered the least surprising behavior. As of version 0.9.7, `format` accepts `:allow-namespaced-names? true` to provide the somewhat unusual behavior of 0.9.0-0.9.6, namely that namespace-qualified keywords were passed through into the SQL "as-is", i.e., with the `/` in them (which generally required a quoting strategy as well). As of version 0.9.8, `format` accepts `:namespace-as-table? true` to treat namespace-qualified keywords as if the `/` were `.`, allowing `:table/column` as an alternative to `:table.column`. This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. @@ -54,13 +58,13 @@ As of version 0.9.8, `format` accepts `:namespace-as-table? true` to treat names (def q-sqlmap {:select [:foo/a :foo/b :foo/c] :from [:foo] :where [:= :foo/a "baz"]}) -(sql/format q-sqlmap :namespace-as-table? true) +(sql/format q-sqlmap) => ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] ``` -Honeysql is a relatively "pure" library, it does not manage your sql connection +HoneySQL is a relatively "pure" library, it does not manage your sql connection or run queries for you, it simply generates SQL strings. You can then pass them -to jdbc: +to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jdbc): ```clj (jdbc/query conn (sql/format sqlmap)) @@ -587,6 +591,6 @@ To teach `honeysql` how to handle your datatype you need to implement [`honeysql ## License -Copyright © 2012-2017 Justin Kramer +Copyright (c) 2020 Sean Corfield. HoneySQL 1.x was copyright (c) 2012-2020 Justin Kramer and Sean Corfield. Distributed under the Eclipse Public License, the same as Clojure. diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn new file mode 100644 index 0000000..b348933 --- /dev/null +++ b/doc/cljdoc.edn @@ -0,0 +1,11 @@ +{:cljdoc.doc/tree [["Readme" {:file "README.md"}] + ["Changes" {:file "CHANGELOG.md"}] + ["Getting Started" {:file "doc/getting-started.md"} + #_["Friendly SQL Functions" {:file "doc/friendly-sql-functions.md"}] + #_["Tips & Tricks" {:file "doc/tips-and-tricks.md"}] + #_["Result Set Builders" {:file "doc/result-set-builders.md"}] + #_["Prepared Statements" {:file "doc/prepared-statements.md"}] + #_["Transactions" {:file "doc/transactions.md"}]] + #_["All The Options" {:file "doc/all-the-options.md"}] + #_["datafy, nav, and :schema" {:file "doc/datafy-nav-and-schema.md"}] + ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md new file mode 100644 index 0000000..22e6bc8 --- /dev/null +++ b/doc/differences-from-1-x.md @@ -0,0 +1,106 @@ +# Differences Between 1.x and 2.x + +The goal of HoneySQL 1.x and earlier was to provide a DSL for vendor-neutral SQL, with the assumption that other libraries would provide the vendor-specific extensions to HoneySQL. HoneySQL 1.x's extension mechanism required quite a bit of internal knowledge (clause priorities and multiple multimethod extension points). It also used a number of custom record types, protocols, and data readers to provide various "escape hatches" in the DSL for representing arrays, function calls (in some situations), inlined values, parameters, and raw SQL, which led to a number of inconsistencies over time, as well as making some things very hard to express while other similar things were easy to express. Addressing bugs caused by vendor-specific differences and by some quirks of how SQL was generated gradually became harder and harder. + +The goal of HoneySQL 2.x is to provide an easily-extensible DSL for SQL, supporting vendor-specific differences and extensions, that is as consistent as possible. A secondary goal is to make maintenance much easier by streamlining the machinery and reducing the number of different ways to write and/or extend the DSL. + +The DSL itself -- the data structures that both versions convert to SQL and parameters via the `format` function -- is almost exactly the same between the two versions so that migration is relatively painless. The primary API -- the `format` function -- is preserved in 2.x, although the variadic options from 1.x have changed to an options hash map in 2.x as this is generally considered more idiomatic. See the **Option Changes** section below for the differences in the options supported. + +## Group, Artifact, and Namespaces + +HoneySQL 2.x uses the group ID `seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). + +In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure is available in `honey.specs` (work in progress). + +### HoneySQL 1.x + +```clojure +;; in deps.edn: +honeysql {:mvn/version "1.0.444"} +;; or, more correctly: +honeysql/honeysql {:mvn/version "1.0.444"} + +;; in use: +(ns my.project + (:require [honeysql.core :as sql])) + +... + (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) + ;;=> ["SELECT * FROM table WHERE id = ?" 1] +``` + +The namespaces were: +* `honeysql.core` -- the primary API (`format`, etc), +* `honeysql.format` -- the logic for the formatting engine, +* `honeysql.helpers` -- helper functions to build the DSL, +* `honeysql.types` -- records, protocols, and data readers, +* `honeysql.util` -- internal utilities (macros). + +### HoneySQL 2.x + +```clojure +;; in deps.edn: +seancorfield/honeysql {:mvn/version "2.x"} + +;; in use: +(ns my.project + (:require [honey.sql :as sql])) + +... + (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) + ;;=> ["SELECT * FROM table WHERE id = ?" 1] +``` + +The new namespaces are: +* `honey.sql` -- the primary API (just `format` now), +* `honey.sql.helpers` -- helper functions to build the DSL, +* `honey.specs` -- a description of the DSL using `clojure.spec.alpha`. + +## API Changes + +The primary API is just `honey.sql/format`. The `array`, `call`, `inline`, `param`, and `raw` functions have all become standard syntax in the DSL as functions (and their tagged literal equivalents have also gone away because they are no longer needed). + +Other `honeysql.core` functions that no longer exist include: `build`, `qualify`, and `quote-identifier`. Many other public functions were essentially undocumented (neither mentioned in the README nor in the tests) and also no longer exist. + +You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialect!` function (which sets a default dialect for all `format` operations) or by passing the new `:dialect` option to the `format` function. `:ansi` is the default dialect (which will mostly incorporate PostgreSQL usage over time). Other dialects supported are `:mysql` (which has a different quoting strategy and uses a different ranking for the `:set` clause), `:oracle` (which is essentially the `:ansi` dialect but will control other things over time), and `:sqlserver` (which is essentially the `:ansi` dialect but with a different quoting strategy) and . Other dialects and changes may be added over time. + +> Note: `:limit` and `:offset` are currently in the default `:ansi` dialect even though they are MySQL-specific. This is temporary as the dialects are being fleshed out. I expect to add `:top` for `:sqlserver` and `:offset` / `:fetch` for `:ansi`, at which point `:limit` / `:offset` will become MySQL-only. + +## Option Changes + +As noted above, the variadic options for `format` have been replaced by a single hash map as the optional second argument to `format`. + +The `:quoting ` option has superseded by the new dialect machinery and a new `:quoted` option that turns quoting on or off. You either use `:dialect ` instead or set a default dialect (via `set-dialect!`) and then use `{:quoted true}` in `format` calls where you want quoting. + +Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. + +The following options are no longer supported: +* `:namespace-as-table?` -- TODO +* `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). + +## DSL Changes + +You can now `SELECT` a function call more easily, using `[[...]]`. This was previously an error -- missing an alias -- but it was a commonly requested change, to avoid using `(sql/call ...)`: + +```clojure + (sql/format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) + ;; select a (column), b (aliased to c), d (fn call), f (fn call, aliased to h): + ;;=> ["SELECT a, b AS c, D(e), F(g) AS h"] + +``` + +The `:set` clause is dialect-dependent. In `:mysql`, it is ranked just before the `:where` clause. In all other dialects, it is ranked just before the `:from` clause. Accordingly, the `:set0` and `:set1` clauses are no longer supported (because they were workarounds in 1.x for this conflict). + +The following new syntax has been added: + +* `:array` -- used as a function to replace the `sql/array` / `#sql/array` machinery, +* `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, +* `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. + +> Note 1: `:inline` currently inlines strings like `"foo"` as `foo` which matches the 1.x behavior but this will almost certainly change to inline as `'foo'`, i.e., a SQL string value, before release. + +> Note 2: expect `:raw` to be added in some form before release. + +## Extensibility + +The protocols and multimethods in 1.x have all gone away. The primary extension point is `honey.sql/register-clause!` which lets you specify the new clause (keyword), the formatter function for it, and the existing clause that it should be ranked before (`format` processes the DSL in clause order). diff --git a/doc/getting-started.md b/doc/getting-started.md new file mode 100644 index 0000000..9fba60b --- /dev/null +++ b/doc/getting-started.md @@ -0,0 +1,3 @@ +# Getting Started with HoneySQL + +tbd diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4bedf59..f0901ae 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -39,13 +39,14 @@ (conj order clause))) (def ^:private dialects - {:ansi {:quote #(str \" % \")} - :mssql {:quote #(str \[ % \])} - :mysql {:quote #(str \` % \`) - :clause-order-fn #(add-clause-before - (filterv (complement #{:set}) %) - :set - :where)}}) + {:ansi {:quote #(str \" % \")} + :sqlserver {:quote #(str \[ % \])} + :mysql {:quote #(str \` % \`) + :clause-order-fn #(add-clause-before + (filterv (complement #{:set}) %) + :set + :where)} + :oracle {:quote #(str \" % \")}}) ; should become defonce (def ^:private default-dialect (atom (:ansi dialects))) @@ -523,7 +524,7 @@ (defn set-dialect! "Set the default dialect for formatting. - Can be: `:ansi` (the default), `:mssql`, `:mysql`. + Can be: `:ansi` (the default), `:mysql`, `:oracle`, or `:sqlserver`. Dialects are always applied to the base order to create the current order." [dialect] @@ -544,9 +545,15 @@ only clause so far where that would matter is `:set` which differs in MySQL..." [clause formatter before] - (swap! base-clause-order add-clause-before clause before) - (swap! current-clause-order add-clause-before clause before) - (swap! clause-format assoc clause formatter)) + (let [f (if (keyword? formatter) + (get @clause-format formatter) + formatter)] + (when-not (and f (fn? f)) + (throw (ex-info "The formatter must be a function or existing clause" + {:type (type formatter)}))) + (swap! base-clause-order add-clause-before clause before) + (swap! current-clause-order add-clause-before clause before) + (swap! clause-format assoc clause f))) (comment (format {:truncate :foo}) @@ -556,6 +563,7 @@ (format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]) (format-expr :id) (format-expr 1) + (format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) (format-on-expr :where [:= :id 1]) (format-dsl {:select [:*] :from [:table] :where [:= :id 1]}) (format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) diff --git a/src/honey/sql/helpers.clj b/src/honey/sql/helpers.clj new file mode 100644 index 0000000..0363db8 --- /dev/null +++ b/src/honey/sql/helpers.clj @@ -0,0 +1,6 @@ +;; copyright (c) 2020 sean corfield, all rights reserved + +(ns honey.sql.helpers + "Macros to create consistent helpers from DSL clauses. + + I don't know how this will work in ClojureScript yet...") diff --git a/src/readme.clj b/src/readme.clj new file mode 100644 index 0000000..1b08643 --- /dev/null +++ b/src/readme.clj @@ -0,0 +1,593 @@ +(ns readme (:require [seancorfield.readme])) + + + + + + + + + + + + + + + + + + + + + + + + + +(seancorfield.readme/defreadme readme-27 +(require '[honey.sql :as sql] + '[honey.sql.helpers :refer :all :as helpers]) +) + + + +(seancorfield.readme/defreadme readme-34 +(def sqlmap {:select [:a :b :c] + :from [:foo] + :where [:= :f.a "baz"]}) +) + + + + + + + +(seancorfield.readme/defreadme readme-46 +(sql/format sqlmap) +=> ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] +) + + + + + +(seancorfield.readme/defreadme readme-55 +(def q-sqlmap {:select [:foo/a :foo/b :foo/c] + :from [:foo] + :where [:= :foo/a "baz"]}) +(sql/format q-sqlmap :namespace-as-table? true) +=> ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] +) + + + + + + + + + + + + + +(seancorfield.readme/defreadme readme-75 +(sql/build :select :* + :from :foo + :where [:= :f.a "baz"]) +=> {:where [:= :f.a "baz"], :from [:foo], :select [:*]} +) + + + +(seancorfield.readme/defreadme readme-84 +(sql/build sqlmap :offset 10 :limit 10) +=> {:limit 10 + :offset 10 + :select [:a :b :c] + :where [:= :f.a "baz"] + :from [:foo]} +) + + + + + +(seancorfield.readme/defreadme readme-97 +(-> (select :a :b :c) + (from :foo) + (where [:= :f.a "baz"])) +) + + + +(seancorfield.readme/defreadme readme-105 +(= (-> (select :*) (from :foo)) + (-> (from :foo) (select :*))) +=> true +) + + + +(seancorfield.readme/defreadme readme-113 +(-> sqlmap (select :*)) +=> '{:from [:foo], :where [:= :f.a "baz"], :select (:*)} +) + + + +(seancorfield.readme/defreadme readme-120 +(-> sqlmap + (merge-select :d :e) + (merge-where [:> :b 10]) + sql/format) +=> ["SELECT a, b, c, d, e FROM foo WHERE (f.a = ? AND b > ?)" "baz" 10] +) + + + +(seancorfield.readme/defreadme readme-130 +(-> (select :*) + (from :foo) + (where [:= :a 1] [:< :b 100]) + sql/format) +=> ["SELECT * FROM foo WHERE (a = ? AND b < ?)" 1 100] +) + + + + +(seancorfield.readme/defreadme readme-141 +(-> (select :a [:b :bar] :c [:d :x]) + (from [:foo :quux]) + (where [:= :quux.a 1] [:< :bar 100]) + sql/format) +=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ? AND bar < ?)" 1 100] +) + + + + + + + + + + +(seancorfield.readme/defreadme readme-158 +(-> (insert-into :properties) + (columns :name :surname :age) + (values + [["Jon" "Smith" 34] + ["Andrew" "Cooper" 12] + ["Jane" "Daniels" 56]]) + sql/format) +=> [#sql/regularize + "INSERT INTO properties (name, surname, age) + VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" + "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] +) + + + + + +(seancorfield.readme/defreadme readme-176 +(-> (insert-into :properties) + (values [{:name "John" :surname "Smith" :age 34} + {:name "Andrew" :surname "Cooper" :age 12} + {:name "Jane" :surname "Daniels" :age 56}]) + sql/format) +=> [#sql/regularize + "INSERT INTO properties (name, surname, age) + VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" + "John" "Smith" 34 + "Andrew" "Cooper" 12 + "Jane" "Daniels" 56] +) + + + + + +(seancorfield.readme/defreadme readme-194 +(let [user-id 12345 + role-name "user"] + (-> (insert-into :user_profile_to_role) + (values [{:user_profile_id user-id + :role_id (-> (select :id) + (from :role) + (where [:= :name role-name]))}]) + sql/format)) + +=> [#sql/regularize + "INSERT INTO user_profile_to_role (user_profile_id, role_id) + VALUES (?, (SELECT id FROM role WHERE name = ?))" + 12345 + "user"] +) + +(seancorfield.readme/defreadme readme-211 +(-> (select :*) + (from :foo) + (where [:in :foo.a (-> (select :a) (from :bar))]) + sql/format) +=> ["SELECT * FROM foo WHERE (foo.a in (SELECT a FROM bar))"] +) + + + + + +(seancorfield.readme/defreadme readme-223 +(-> (insert-into :comp_table) + (columns :name :comp_column) + (values + [["small" (composite 1 "inch")] + ["large" (composite 10 "feet")]]) + sql/format) +=> [#sql/regularize + "INSERT INTO comp_table (name, comp_column) + VALUES (?, (?, ?)), (?, (?, ?))" + "small" 1 "inch" "large" 10 "feet"] +) + + + + + + +(seancorfield.readme/defreadme readme-241 +(-> (helpers/update :films) + (sset {:kind "dramatic" + :watched (sql/call :+ :watched 1)}) + (where [:= :kind "drama"]) + sql/format) +=> [#sql/regularize + "UPDATE films SET kind = ?, watched = (watched + ?) + WHERE kind = ?" + "dramatic" + 1 + "drama"] +) + + + + + + + + + + + + + +(seancorfield.readme/defreadme readme-267 +(-> (delete-from :films) + (where [:<> :kind "musical"]) + sql/format) +=> ["DELETE FROM films WHERE kind <> ?" "musical"] +) + + + +(seancorfield.readme/defreadme readme-276 +(-> (delete [:films :directors]) + (from :films) + (join :directors [:= :films.director_id :directors.id]) + (where [:<> :kind "musical"]) + sql/format) +=> [#sql/regularize + "DELETE films, directors + FROM films + INNER JOIN directors ON films.director_id = directors.id + WHERE kind <> ?" + "musical"] +) + + + +(seancorfield.readme/defreadme readme-292 +(-> (truncate :films) + sql/format) +=> ["TRUNCATE films"] +) + + + + + +(seancorfield.readme/defreadme readme-302 +(sql/format {:union [(-> (select :*) (from :foo)) + (-> (select :*) (from :bar))]}) +=> ["SELECT * FROM foo UNION SELECT * FROM bar"] +) + + + + + +(seancorfield.readme/defreadme readme-312 +(-> (select :%count.*) (from :foo) sql/format) +=> ["SELECT count(*) FROM foo"] +) +(seancorfield.readme/defreadme readme-316 +(-> (select :%max.id) (from :foo) sql/format) +=> ["SELECT max(id) FROM foo"] +) + + + + + +(seancorfield.readme/defreadme readme-325 +(-> (select :id) + (from :foo) + (where [:= :a :?baz]) + (sql/format :params {:baz "BAZ"})) +=> ["SELECT id FROM foo WHERE a = ?" "BAZ"] +) + + + + + + +(seancorfield.readme/defreadme readme-338 +(def call-qualify-map + (-> (select (sql/call :foo :bar) (sql/qualify :foo :a) (sql/raw "@var := foo.bar")) + (from :foo) + (where [:= :a (sql/param :baz)] [:= :b (sql/inline 42)]))) +) +(seancorfield.readme/defreadme readme-344 +call-qualify-map +=> '{:where [:and [:= :a #sql/param :baz] [:= :b #sql/inline 42]] + :from (:foo) + :select (#sql/call [:foo :bar] :foo.a #sql/raw "@var := foo.bar")} +) +(seancorfield.readme/defreadme readme-350 +(sql/format call-qualify-map :params {:baz "BAZ"}) +=> ["SELECT foo(bar), foo.a, @var := foo.bar FROM foo WHERE (a = ? AND b = 42)" "BAZ"] +) + + + + + + +(seancorfield.readme/defreadme readme-360 +(-> (insert-into :sample) + (values [{:location (sql/call :ST_SetSRID + (sql/call :ST_MakePoint 0.291 32.621) + (sql/call :cast 4326 :integer))}]) + (sql/format)) +=> [#sql/regularize + "INSERT INTO sample (location) + VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer)))" + 0.291 32.621 4326] +) + + + + + + + + + + + + +(seancorfield.readme/defreadme readme-383 +(-> (select :*) + (from :foo) + (where [:< :expired_at (sql/raw ["now() - '" 5 " seconds'"])]) + (sql/format {:foo 5})) +=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] +) + +(seancorfield.readme/defreadme readme-391 +(-> (select :*) + (from :foo) + (where [:< :expired_at (sql/raw ["now() - '" #sql/param :t " seconds'"])]) + (sql/format {:t 5})) +=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] +) + + + + + +(seancorfield.readme/defreadme readme-403 +(-> (select :foo.a) + (from :foo) + (where [:= :foo.a "baz"]) + (sql/format :quoting :mysql)) +=> ["SELECT `foo`.`a` FROM `foo` WHERE `foo`.`a` = ?" "baz"] +) + + + + + + + +(seancorfield.readme/defreadme readme-417 +(-> (select :foo.a) + (from :foo) + (where [:= :foo.a "baz"]) + (lock :mode :update) + (sql/format)) +=> ["SELECT foo.a FROM foo WHERE foo.a = ? FOR UPDATE" "baz"] +) + + + + +(seancorfield.readme/defreadme readme-429 +(sql/format + {:select [:f.foo-id :f.foo-name] + :from [[:foo-bar :f]] + :where [:= :f.foo-id 12345]} + :allow-dashed-names? true + :quoting :ansi) +=> ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] +) + + + + + +(seancorfield.readme/defreadme readme-443 +(def big-complicated-map + (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] + (sql/call :now) (sql/raw "@x := 10")) + (modifiers :distinct) + (from [:foo :f] [:baz :b]) + (join :draq [:= :f.b :draq.x]) + (left-join [:clod :c] [:= :f.a :c.d]) + (right-join :bock [:= :bock.z :c.e]) + (where [:or + [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:< 1 2 3] + [:in :f.e [1 (sql/param :param2) 3]] + [:between :f.e 10 20]]) + (group :f.a :c.e) + (having [:< 0 :f.e]) + (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) + (limit 50) + (offset 10))) +) +(seancorfield.readme/defreadme readme-463 +big-complicated-map +=> {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] + (sql/call :now) (sql/raw "@x := 10")] + :modifiers [:distinct] + :from [[:foo :f] [:baz :b]] + :join [:draq [:= :f.b :draq.x]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :right-join [:bock [:= :bock.z :c.e]] + :where [:or + [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:< 1 2 3] + [:in :f.e [1 (sql/param :param2) 3]] + [:between :f.e 10 20]] + :group-by [:f.a :c.e] + :having [:< 0 :f.e] + :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] + :limit 50 + :offset 10} +) +(seancorfield.readme/defreadme readme-483 +(sql/format big-complicated-map {:param1 "gabba" :param2 2}) +=> [#sql/regularize + "SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 + FROM foo f, baz b + INNER JOIN draq ON f.b = draq.x + LEFT JOIN clod c ON f.a = c.d + RIGHT JOIN bock ON bock.z = c.e + WHERE ((f.a = ? AND b.baz <> ?) + OR (? < ? AND ? < ?) + OR (f.e in (?, ?, ?)) + OR f.e BETWEEN ? AND ?) + GROUP BY f.a, c.e + HAVING ? < f.e + ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST + LIMIT ? + OFFSET ? " + "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] +) +(seancorfield.readme/defreadme readme-502 +;; Printable and readable +(= big-complicated-map (read-string (pr-str big-complicated-map))) +=> true +) + + + + + +(seancorfield.readme/defreadme readme-512 +(require '[honeysql.format :as fmt]) +) +(seancorfield.readme/defreadme readme-515 +(defmethod fmt/fn-handler "betwixt" [_ field lower upper] + (str (fmt/to-sql field) " BETWIXT " + (fmt/to-sql lower) " AND " (fmt/to-sql upper))) + +(-> (select :a) (where [:betwixt :a 1 10]) sql/format) +=> ["SELECT a WHERE a BETWIXT ? AND ?" 1 10] +) + + + +(seancorfield.readme/defreadme readme-526 +;; Takes a MapEntry of the operator & clause data, plus the entire SQL map +(defmethod fmt/format-clause :foobar [[op v] sqlmap] + (str "FOOBAR " (fmt/to-sql v))) +) +(seancorfield.readme/defreadme readme-531 +(sql/format {:select [:a :b] :foobar :baz}) +=> ["SELECT a, b FOOBAR baz"] +) +(seancorfield.readme/defreadme readme-535 +(require '[honeysql.helpers :refer [defhelper]]) + +;; Defines a helper function, and allows 'build' to recognize your clause +(defhelper foobar [m args] + (assoc m :foobar (first args))) +) +(seancorfield.readme/defreadme readme-542 +(-> (select :a :b) (foobar :baz) sql/format) +=> ["SELECT a, b FOOBAR baz"] + +) + + + +(seancorfield.readme/defreadme readme-550 +(fmt/register-clause! :foobar 110) +) + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + + diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3f290e3..90c5844 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -108,9 +108,12 @@ ;; EXISTS should never have been implemented as SQL syntax: it's an operator! #_(is (= (format {:exists {:select [:a] :from [:foo]}}) ["EXISTS (SELECT a FROM foo)"])) - ;; ugly because it's hard to select just a function call without an alias: + ;; select function call with an alias: (is (= (format {:select [[[:exists {:select [:a] :from [:foo]}] :x]]}) ["SELECT EXISTS (SELECT a FROM foo) AS x"])) + ;; select function call with no alias required: + (is (= (format {:select [[[:exists {:select [:a] :from [:foo]}]]]}) + ["SELECT EXISTS (SELECT a FROM foo)"])) (is (= (format {:select [:id] :from [:foo] :where [:exists {:select [1] diff --git a/src/honeysql/core.cljc b/test/honeysql/core.cljc similarity index 100% rename from src/honeysql/core.cljc rename to test/honeysql/core.cljc diff --git a/src/honeysql/format.cljc b/test/honeysql/format.cljc similarity index 100% rename from src/honeysql/format.cljc rename to test/honeysql/format.cljc diff --git a/src/honeysql/helpers.cljc b/test/honeysql/helpers.cljc similarity index 100% rename from src/honeysql/helpers.cljc rename to test/honeysql/helpers.cljc diff --git a/src/honeysql/types.cljc b/test/honeysql/types.cljc similarity index 100% rename from src/honeysql/types.cljc rename to test/honeysql/types.cljc diff --git a/src/honeysql/util.clj b/test/honeysql/util.clj similarity index 100% rename from src/honeysql/util.clj rename to test/honeysql/util.clj From 1c7e08bb82835a8819bd987f090731cb7dd4a92b Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 24 Sep 2020 20:49:22 -0700 Subject: [PATCH 015/254] A first pass over the README for V2 --- README.md | 130 +++++++++++++++++++++++++----------------------------- 1 file changed, 61 insertions(+), 69 deletions(-) diff --git a/README.md b/README.md index b1d0e3f..3a1b611 100644 --- a/README.md +++ b/README.md @@ -48,6 +48,16 @@ Column names can be provided as keywords or symbols (but not strings -- HoneySQL => ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] ``` +HoneySQL is a relatively "pure" library, it does not manage your sql connection +or run queries for you, it simply generates SQL strings. You can then pass them +to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jdbc): + +```clj +(jdbc/execute! conn (sql/format sqlmap)) +``` + +> Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you. + _The handling of namespace-qualified keywords is under review in 2.x._ By default, namespace-qualified keywords are treated as simple keywords: their namespace portion is ignored. This was the behavior in HoneySQL prior to the 0.9.0 release and has been restored since the 0.9.7 release as this is considered the least surprising behavior. @@ -62,39 +72,11 @@ As of version 0.9.8, `format` accepts `:namespace-as-table? true` to treat names => ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] ``` -HoneySQL is a relatively "pure" library, it does not manage your sql connection -or run queries for you, it simply generates SQL strings. You can then pass them -to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jdbc): - -```clj -(jdbc/query conn (sql/format sqlmap)) -``` - -### `build` - -You can build up SQL maps yourself or use helper functions. `build` is the Swiss Army Knife helper. It lets you leave out brackets here and there: - -```clojure -(sql/build :select :* - :from :foo - :where [:= :f.a "baz"]) -=> {:where [:= :f.a "baz"], :from [:foo], :select [:*]} -``` - -You can provide a "base" map as the first argument to build: - -```clojure -(sql/build sqlmap :offset 10 :limit 10) -=> {:limit 10 - :offset 10 - :select [:a :b :c] - :where [:= :f.a "baz"] - :from [:foo]} -``` - ### Vanilla SQL clause helpers -There are also functions for each clause type in the `honeysql.helpers` namespace: +_The code behind this section is a work-in-progress._ + +There are also functions for each clause type in the `honey.sql.helpers` namespace: ```clojure (-> (select :a :b :c) @@ -102,7 +84,7 @@ There are also functions for each clause type in the `honeysql.helpers` namespac (where [:= :f.a "baz"])) ``` -Order doesn't matter: +Order doesn't matter (for independent clauses): ```clojure (= (-> (select :*) (from :foo)) @@ -110,21 +92,22 @@ Order doesn't matter: => true ``` -When using the vanilla helper functions, new clauses will replace old clauses: +When using the vanilla helper functions, repeated clauses will be merged into existing clauses (where that makes sense): ```clojure -(-> sqlmap (select :*)) -=> '{:from [:foo], :where [:= :f.a "baz"], :select (:*)} +(-> sqlmap (select :d)) +=> '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} ``` -To add to clauses instead of replacing them, use `merge-select`, `merge-where`, etc.: +If you want to replace a clause, you can `dissoc` the existing clause first, since this is all data: ```clojure (-> sqlmap - (merge-select :d :e) - (merge-where [:> :b 10]) + (dissoc :select) + (select :*) + (where [:> :b 10]) sql/format) -=> ["SELECT a, b, c, d, e FROM foo WHERE (f.a = ? AND b > ?)" "baz" 10] +=> ["SELECT * FROM foo WHERE (f.a = ?) AND (b > ?)" "baz" 10] ``` `where` will combine multiple clauses together using SQL's `AND`: @@ -134,7 +117,7 @@ To add to clauses instead of replacing them, use `merge-select`, `merge-where`, (from :foo) (where [:= :a 1] [:< :b 100]) sql/format) -=> ["SELECT * FROM foo WHERE (a = ? AND b < ?)" 1 100] +=> ["SELECT * FROM foo WHERE (a = ?) AND (b < ?)" 1 100] ``` Column and table names may be aliased by using a vector pair of the original @@ -145,7 +128,7 @@ name and the desired alias: (from [:foo :quux]) (where [:= :quux.a 1] [:< :bar 100]) sql/format) -=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ? AND bar < ?)" 1 100] +=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ?) AND (bar < ?)" 1 100] ``` In particular, note that `(select [:a :b])` means `SELECT a AS b` rather than @@ -256,11 +239,10 @@ with `clojure.core/set`): If you are trying to build a compound update statement (with `from` or `join`), be aware that different databases have slightly different syntax in terms of -where `SET` should appear. The default above is to put `SET` after any `JOIN`. -There are two variants of `sset` (and the underlying `:set` in the SQL map): - -* `set0` (and `:set0`) -- this puts the `SET` before `FROM`, -* `set1` (and `:set1`) -- a synonym for `sset` (and `:set`) that puts the `SET` after `JOIN`. +where `SET` should appear. The default above is to put `SET` before `FROM` which +is how PostgreSQL (and other ANSI-SQL dialects work). If you are using MySQL, +you will need to select the `:mysql` dialect in order to put the `SET` after +any `JOIN` clause. ### Deletes @@ -322,6 +304,8 @@ Keywords that begin with `%` are interpreted as SQL function calls: ### Bindable parameters +_This is not currently supported._ + Keywords that begin with `?` are interpreted as bindable parameters: ```clojure @@ -334,24 +318,24 @@ Keywords that begin with `?` are interpreted as bindable parameters: ### Miscellaneous -There are helper functions and data literals for SQL function calls, field -qualifiers, raw SQL fragments, inline values, and named input parameters: +TODO: need to update this section to reflect how to select a function call, how +to identify inline parameter values, and how to add in raw SQL fragments! ```clojure (def call-qualify-map - (-> (select (sql/call :foo :bar) (sql/qualify :foo :a) (sql/raw "@var := foo.bar")) + (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) - (where [:= :a (sql/param :baz)] [:= :b (sql/inline 42)]))) + (where [:= :a (???/param :baz)] [:= :b [:inline 42]]))) ``` ```clojure call-qualify-map -=> '{:where [:and [:= :a #sql/param :baz] [:= :b #sql/inline 42]] +=> '{:where [:and [:= :a ???/param :baz] [:= :b [:inline 42]]] :from (:foo) - :select (#sql/call [:foo :bar] :foo.a #sql/raw "@var := foo.bar")} + :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ``` ```clojure -(sql/format call-qualify-map :params {:baz "BAZ"}) -=> ["SELECT foo(bar), foo.a, @var := foo.bar FROM foo WHERE (a = ? AND b = 42)" "BAZ"] +(sql/format call-qualify-map :??? {:baz "BAZ"}) +=> ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ``` #### PostGIS @@ -361,9 +345,9 @@ have a lot of function calls needed in code: ```clojure (-> (insert-into :sample) - (values [{:location (sql/call :ST_SetSRID - (sql/call :ST_MakePoint 0.291 32.621) - (sql/call :cast 4326 :integer))}]) + (values [{:location [:ST_SetSRID + [:ST_MakePoint 0.291 32.621] + [:cast 4325 :integer]]}]) (sql/format)) => [#sql/regularize "INSERT INTO sample (location) @@ -373,6 +357,8 @@ have a lot of function calls needed in code: #### Raw SQL fragments +_This functionality is under review._ + Raw SQL fragments that are strings are treated exactly as-is when rendered into the formatted SQL string (with no parsing or parameterization). Inline values will not be lifted out as parameters, so they end up in the SQL string as-is. @@ -400,18 +386,25 @@ or the `param` helper. #### Identifiers -To quote identifiers, pass the `:quoting` keyword option to `format`. Valid options are `:ansi` (PostgreSQL), `:mysql`, or `:sqlserver`: +To quote identifiers, pass the `:quoted true` option to `format` and they will +be quoted according to the selected dialect. If you override the dialect in a +`format` call, by passing the `:dialect` option, identifiers will be automatically +quoted. You can override the dialect and turn off quoting by passing `:quoted false`. +Valid `:dialect` options are `:ansi` (the default, use this for PostgreSQL), +`:mysql`, `:oracle`, or `:sqlserver`: ```clojure (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) - (sql/format :quoting :mysql)) + (sql/format {:dialect :mysql})) => ["SELECT `foo`.`a` FROM `foo` WHERE `foo`.`a` = ?" "baz"] ``` #### Locking +_This is not implemented yet._ + To issue a locking select, add a `:lock` to the query or use the lock helper. The lock value must be a map with a `:mode` value. The built-in modes are the standard `:update` (FOR UPDATE) or the vendor-specific `:mysql-share` (LOCK IN SHARE MODE) or `:postresql-share` (FOR SHARE). The lock map may also provide a `:wait` value, which if false will append the NOWAIT parameter, supported by PostgreSQL. @@ -445,16 +438,16 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify ```clojure (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] - (sql/call :now) (sql/raw "@x := 10")) - (modifiers :distinct) + [[:now]] [[:raw "@x := 10"]]) + (modifiers :distinct) ; this is not implemented yet (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) (right-join :bock [:= :bock.z :c.e]) (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] + [:in :f.e [1 (???/param :param2) 3]] [:between :f.e 10 20]]) (group :f.a :c.e) (having [:< 0 :f.e]) @@ -465,16 +458,16 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify ```clojure big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] - (sql/call :now) (sql/raw "@x := 10")] + [[:now]] [[:raw "@x := 10"]]] :modifiers [:distinct] :from [[:foo :f] [:baz :b]] :join [:draq [:= :f.b :draq.x]] :left-join [[:clod :c] [:= :f.a :c.d]] :right-join [:bock [:= :bock.z :c.e]] :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] + [:in :f.e [1 (????/param :param2) 3]] [:between :f.e 10 20]] :group-by [:f.a :c.e] :having [:< 0 :f.e] @@ -509,11 +502,10 @@ big-complicated-map ## Extensibility +_This needs a rewrite!_ + You can define your own function handlers for use in `where`: -```clojure -(require '[honeysql.format :as fmt]) -``` ```clojure (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " From 9f20ade0fe867a0f0157faa2dd1b323b2cb83b19 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 15:31:11 -0700 Subject: [PATCH 016/254] Fix is/not null generation --- src/honey/sql.cljc | 30 +++++++++++++++++++----------- test/honey/sql_test.cljc | 15 +++++++++++++++ 2 files changed, 34 insertions(+), 11 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f0901ae..d446b3c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -463,17 +463,24 @@ (let [op (first x)] (if (keyword? op) (cond (infix-ops op) - (let [[_ a b] x + (let [[_ a b] x [s1 & p1] (format-expr a {:nested? true}) - [s2 & p2] (format-expr b {:nested? true})] - (-> (str s1 " " - (sql-kw (get infix-aliases op op)) - " " s2) - (cond-> nested? - (as-> s (str "(" s ")"))) - (vector) - (into p1) - (into p2))) + [s2 & p2] (format-expr b {:nested? true}) + op (get infix-aliases op op)] + (if (and (#{:= :<>} op) (or (nil? a) (nil? b))) + (-> (str (if (nil? a) + (if (nil? b) "NULL" s2) + s1) + (if (= := op) " IS NULL" " IS NOT NULL")) + (cond-> nested? + (as-> s (str "(" s ")"))) + (vector)) + (-> (str s1 " " (sql-kw op) " " s2) + (cond-> nested? + (as-> s (str "(" s ")"))) + (vector) + (into p1) + (into p2)))) (special-syntax op) (let [formatter (special-syntax op)] (formatter (rest x))) @@ -573,6 +580,7 @@ (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) - (format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (format {:select [:*] :from [:table] :where [:= :id (int 1)]} {:dialect :mysql}) + (map fn? (format {:select [:*] :from [:table] :where [:= :id (with-meta (constantly 42) {:foo true})]} {:dialect :mysql})) (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {}) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 90c5844..f843c76 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -12,6 +12,21 @@ {:dialect :mysql})))) (deftest expr-tests + (is (= ["id IS NULL"] + (sut/format-expr [:= :id nil]))) + (is (= ["id IS NULL"] + (sut/format-expr [:is :id nil]))) + (is (= ["id IS NOT NULL"] + (sut/format-expr [:<> :id nil]))) + (is (= ["id IS NOT NULL"] + (sut/format-expr [:!= :id nil]))) + (is (= ["id IS NOT NULL"] + (sut/format-expr [:is-not :id nil]))) + ;; degenerate cases: + (is (= ["NULL IS NULL"] + (sut/format-expr [:= nil nil]))) + (is (= ["NULL IS NOT NULL"] + (sut/format-expr [:<> nil nil]))) (is (= ["id = ?" 1] (sut/format-expr [:= :id 1]))) (is (= ["id + ?" 1] From 63a079ca8dcd7588d01a1fa1ae89748f08adf199 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 15:31:29 -0700 Subject: [PATCH 017/254] Bump readme version (and gen'd code) --- deps.edn | 2 +- src/readme.clj | 186 ++++++++++++++++++++++++------------------------- 2 files changed, 91 insertions(+), 97 deletions(-) diff --git a/deps.edn b/deps.edn index 3711619..fd1fedc 100644 --- a/deps.edn +++ b/deps.edn @@ -16,7 +16,7 @@ "-d" "test"]} :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.7.0"}} :main-opts ["-m" "cljs-test-runner.main"]} - :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.13"}} + :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} diff --git a/src/readme.clj b/src/readme.clj index 1b08643..d6f4b75 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -52,11 +52,23 @@ -(seancorfield.readme/defreadme readme-55 + + + + + + + + + + + + +(seancorfield.readme/defreadme readme-67 (def q-sqlmap {:select [:foo/a :foo/b :foo/c] :from [:foo] :where [:= :foo/a "baz"]}) -(sql/format q-sqlmap :namespace-as-table? true) +(sql/format q-sqlmap) => ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] ) @@ -66,35 +78,7 @@ - - - - - - -(seancorfield.readme/defreadme readme-75 -(sql/build :select :* - :from :foo - :where [:= :f.a "baz"]) -=> {:where [:= :f.a "baz"], :from [:foo], :select [:*]} -) - - - -(seancorfield.readme/defreadme readme-84 -(sql/build sqlmap :offset 10 :limit 10) -=> {:limit 10 - :offset 10 - :select [:a :b :c] - :where [:= :f.a "baz"] - :from [:foo]} -) - - - - - -(seancorfield.readme/defreadme readme-97 +(seancorfield.readme/defreadme readme-81 (-> (select :a :b :c) (from :foo) (where [:= :f.a "baz"])) @@ -102,7 +86,7 @@ -(seancorfield.readme/defreadme readme-105 +(seancorfield.readme/defreadme readme-89 (= (-> (select :*) (from :foo)) (-> (from :foo) (select :*))) => true @@ -110,40 +94,41 @@ -(seancorfield.readme/defreadme readme-113 -(-> sqlmap (select :*)) -=> '{:from [:foo], :where [:= :f.a "baz"], :select (:*)} +(seancorfield.readme/defreadme readme-97 +(-> sqlmap (select :d)) +=> '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} ) -(seancorfield.readme/defreadme readme-120 +(seancorfield.readme/defreadme readme-104 (-> sqlmap - (merge-select :d :e) - (merge-where [:> :b 10]) + (dissoc :select) + (select :*) + (where [:> :b 10]) sql/format) -=> ["SELECT a, b, c, d, e FROM foo WHERE (f.a = ? AND b > ?)" "baz" 10] +=> ["SELECT * FROM foo WHERE (f.a = ?) AND (b > ?)" "baz" 10] ) -(seancorfield.readme/defreadme readme-130 +(seancorfield.readme/defreadme readme-115 (-> (select :*) (from :foo) (where [:= :a 1] [:< :b 100]) sql/format) -=> ["SELECT * FROM foo WHERE (a = ? AND b < ?)" 1 100] +=> ["SELECT * FROM foo WHERE (a = ?) AND (b < ?)" 1 100] ) -(seancorfield.readme/defreadme readme-141 +(seancorfield.readme/defreadme readme-126 (-> (select :a [:b :bar] :c [:d :x]) (from [:foo :quux]) (where [:= :quux.a 1] [:< :bar 100]) sql/format) -=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ? AND bar < ?)" 1 100] +=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ?) AND (bar < ?)" 1 100] ) @@ -155,7 +140,7 @@ -(seancorfield.readme/defreadme readme-158 +(seancorfield.readme/defreadme readme-143 (-> (insert-into :properties) (columns :name :surname :age) (values @@ -173,7 +158,7 @@ -(seancorfield.readme/defreadme readme-176 +(seancorfield.readme/defreadme readme-161 (-> (insert-into :properties) (values [{:name "John" :surname "Smith" :age 34} {:name "Andrew" :surname "Cooper" :age 12} @@ -191,7 +176,7 @@ -(seancorfield.readme/defreadme readme-194 +(seancorfield.readme/defreadme readme-179 (let [user-id 12345 role-name "user"] (-> (insert-into :user_profile_to_role) @@ -208,7 +193,7 @@ "user"] ) -(seancorfield.readme/defreadme readme-211 +(seancorfield.readme/defreadme readme-196 (-> (select :*) (from :foo) (where [:in :foo.a (-> (select :a) (from :bar))]) @@ -220,7 +205,7 @@ -(seancorfield.readme/defreadme readme-223 +(seancorfield.readme/defreadme readme-208 (-> (insert-into :comp_table) (columns :name :comp_column) (values @@ -238,7 +223,7 @@ -(seancorfield.readme/defreadme readme-241 +(seancorfield.readme/defreadme readme-226 (-> (helpers/update :films) (sset {:kind "dramatic" :watched (sql/call :+ :watched 1)}) @@ -263,8 +248,7 @@ - -(seancorfield.readme/defreadme readme-267 +(seancorfield.readme/defreadme readme-251 (-> (delete-from :films) (where [:<> :kind "musical"]) sql/format) @@ -273,7 +257,7 @@ -(seancorfield.readme/defreadme readme-276 +(seancorfield.readme/defreadme readme-260 (-> (delete [:films :directors]) (from :films) (join :directors [:= :films.director_id :directors.id]) @@ -289,7 +273,7 @@ -(seancorfield.readme/defreadme readme-292 +(seancorfield.readme/defreadme readme-276 (-> (truncate :films) sql/format) => ["TRUNCATE films"] @@ -299,7 +283,7 @@ -(seancorfield.readme/defreadme readme-302 +(seancorfield.readme/defreadme readme-286 (sql/format {:union [(-> (select :*) (from :foo)) (-> (select :*) (from :bar))]}) => ["SELECT * FROM foo UNION SELECT * FROM bar"] @@ -309,11 +293,11 @@ -(seancorfield.readme/defreadme readme-312 +(seancorfield.readme/defreadme readme-296 (-> (select :%count.*) (from :foo) sql/format) => ["SELECT count(*) FROM foo"] ) -(seancorfield.readme/defreadme readme-316 +(seancorfield.readme/defreadme readme-300 (-> (select :%max.id) (from :foo) sql/format) => ["SELECT max(id) FROM foo"] ) @@ -322,7 +306,9 @@ -(seancorfield.readme/defreadme readme-325 + + +(seancorfield.readme/defreadme readme-311 (-> (select :id) (from :foo) (where [:= :a :?baz]) @@ -335,21 +321,21 @@ -(seancorfield.readme/defreadme readme-338 +(seancorfield.readme/defreadme readme-324 (def call-qualify-map - (-> (select (sql/call :foo :bar) (sql/qualify :foo :a) (sql/raw "@var := foo.bar")) + (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) - (where [:= :a (sql/param :baz)] [:= :b (sql/inline 42)]))) + (where [:= :a (???/param :baz)] [:= :b [:inline 42]]))) ) -(seancorfield.readme/defreadme readme-344 +(seancorfield.readme/defreadme readme-330 call-qualify-map -=> '{:where [:and [:= :a #sql/param :baz] [:= :b #sql/inline 42]] +=> '{:where [:and [:= :a ???/param :baz] [:= :b [:inline 42]]] :from (:foo) - :select (#sql/call [:foo :bar] :foo.a #sql/raw "@var := foo.bar")} + :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ) -(seancorfield.readme/defreadme readme-350 -(sql/format call-qualify-map :params {:baz "BAZ"}) -=> ["SELECT foo(bar), foo.a, @var := foo.bar FROM foo WHERE (a = ? AND b = 42)" "BAZ"] +(seancorfield.readme/defreadme readme-336 +(sql/format call-qualify-map :??? {:baz "BAZ"}) +=> ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ) @@ -357,11 +343,11 @@ call-qualify-map -(seancorfield.readme/defreadme readme-360 +(seancorfield.readme/defreadme readme-346 (-> (insert-into :sample) - (values [{:location (sql/call :ST_SetSRID - (sql/call :ST_MakePoint 0.291 32.621) - (sql/call :cast 4326 :integer))}]) + (values [{:location [:ST_SetSRID + [:ST_MakePoint 0.291 32.621] + [:cast 4325 :integer]]}]) (sql/format)) => [#sql/regularize "INSERT INTO sample (location) @@ -380,7 +366,9 @@ call-qualify-map -(seancorfield.readme/defreadme readme-383 + + +(seancorfield.readme/defreadme readme-371 (-> (select :*) (from :foo) (where [:< :expired_at (sql/raw ["now() - '" 5 " seconds'"])]) @@ -388,7 +376,7 @@ call-qualify-map => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ) -(seancorfield.readme/defreadme readme-391 +(seancorfield.readme/defreadme readme-379 (-> (select :*) (from :foo) (where [:< :expired_at (sql/raw ["now() - '" #sql/param :t " seconds'"])]) @@ -400,11 +388,16 @@ call-qualify-map -(seancorfield.readme/defreadme readme-403 + + + + + +(seancorfield.readme/defreadme readme-396 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) - (sql/format :quoting :mysql)) + (sql/format {:dialect :mysql})) => ["SELECT `foo`.`a` FROM `foo` WHERE `foo`.`a` = ?" "baz"] ) @@ -414,7 +407,9 @@ call-qualify-map -(seancorfield.readme/defreadme readme-417 + + +(seancorfield.readme/defreadme readme-412 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -426,7 +421,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-429 +(seancorfield.readme/defreadme readme-424 (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] @@ -440,19 +435,19 @@ call-qualify-map -(seancorfield.readme/defreadme readme-443 +(seancorfield.readme/defreadme readme-438 (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] - (sql/call :now) (sql/raw "@x := 10")) - (modifiers :distinct) + [[:now]] [[:raw "@x := 10"]]) + (modifiers :distinct) ; this is not implemented yet (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) (right-join :bock [:= :bock.z :c.e]) (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] + [:in :f.e [1 (???/param :param2) 3]] [:between :f.e 10 20]]) (group :f.a :c.e) (having [:< 0 :f.e]) @@ -460,19 +455,19 @@ call-qualify-map (limit 50) (offset 10))) ) -(seancorfield.readme/defreadme readme-463 +(seancorfield.readme/defreadme readme-458 big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] - (sql/call :now) (sql/raw "@x := 10")] + [[:now]] [[:raw "@x := 10"]]] :modifiers [:distinct] :from [[:foo :f] [:baz :b]] :join [:draq [:= :f.b :draq.x]] :left-join [[:clod :c] [:= :f.a :c.d]] :right-join [:bock [:= :bock.z :c.e]] :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (sql/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] + [:in :f.e [1 (????/param :param2) 3]] [:between :f.e 10 20]] :group-by [:f.a :c.e] :having [:< 0 :f.e] @@ -480,7 +475,7 @@ big-complicated-map :limit 50 :offset 10} ) -(seancorfield.readme/defreadme readme-483 +(seancorfield.readme/defreadme readme-478 (sql/format big-complicated-map {:param1 "gabba" :param2 2}) => [#sql/regularize "SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 @@ -499,7 +494,7 @@ big-complicated-map OFFSET ? " "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ) -(seancorfield.readme/defreadme readme-502 +(seancorfield.readme/defreadme readme-497 ;; Printable and readable (= big-complicated-map (read-string (pr-str big-complicated-map))) => true @@ -509,10 +504,9 @@ big-complicated-map -(seancorfield.readme/defreadme readme-512 -(require '[honeysql.format :as fmt]) -) -(seancorfield.readme/defreadme readme-515 + + +(seancorfield.readme/defreadme readme-509 (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " (fmt/to-sql lower) " AND " (fmt/to-sql upper))) @@ -523,23 +517,23 @@ big-complicated-map -(seancorfield.readme/defreadme readme-526 +(seancorfield.readme/defreadme readme-520 ;; Takes a MapEntry of the operator & clause data, plus the entire SQL map (defmethod fmt/format-clause :foobar [[op v] sqlmap] (str "FOOBAR " (fmt/to-sql v))) ) -(seancorfield.readme/defreadme readme-531 +(seancorfield.readme/defreadme readme-525 (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] ) -(seancorfield.readme/defreadme readme-535 +(seancorfield.readme/defreadme readme-529 (require '[honeysql.helpers :refer [defhelper]]) ;; Defines a helper function, and allows 'build' to recognize your clause (defhelper foobar [m args] (assoc m :foobar (first args))) ) -(seancorfield.readme/defreadme readme-542 +(seancorfield.readme/defreadme readme-536 (-> (select :a :b) (foobar :baz) sql/format) => ["SELECT a, b FOOBAR baz"] @@ -547,7 +541,7 @@ big-complicated-map -(seancorfield.readme/defreadme readme-550 +(seancorfield.readme/defreadme readme-544 (fmt/register-clause! :foobar 110) ) From 1ebbbc177271845e8b45d234df7d5e749bd5756a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 16:38:11 -0700 Subject: [PATCH 018/254] Fix inline string behavior --- doc/differences-from-1-x.md | 2 +- src/honey/sql.cljc | 2 +- test/honey/sql_test.cljc | 3 ++- 3 files changed, 4 insertions(+), 3 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 22e6bc8..ab94f6a 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -97,7 +97,7 @@ The following new syntax has been added: * `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, * `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. -> Note 1: `:inline` currently inlines strings like `"foo"` as `foo` which matches the 1.x behavior but this will almost certainly change to inline as `'foo'`, i.e., a SQL string value, before release. +> Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). > Note 2: expect `:raw` to be added in some form before release. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index d446b3c..72f1ef4 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -421,7 +421,7 @@ (defn- sqlize-value [x] (cond (nil? x) "NULL" - (string? x) x ; I feel this should be 'single-quoted' but 1.x does not + (string? x) (str \' (str/replace x "'" "''") \') (symbol? x) (name x) (keyword? x) (name x) :else (str x))) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index f843c76..793e033 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -309,8 +309,9 @@ (format {:dialect :mysql}))))) (deftest inlined-values-are-stringified-correctly - (is (= ["SELECT foo, bar, NULL"] + (is (= ["SELECT 'foo', 'It''s a quote!', bar, NULL"] (format {:select [[[:inline "foo"]] + [[:inline "It's a quote!"]] [[:inline :bar]] [[:inline nil]]]})))) From a6c1f98b71741afd2c4f3e59f4a961c1e0d513a6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 16:38:38 -0700 Subject: [PATCH 019/254] Fix CTE syntax Should always be wrapped in parens --- src/honey/sql.cljc | 6 ++---- test/honey/sql_test.cljc | 4 ++-- 2 files changed, 4 insertions(+), 6 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 72f1ef4..0dd9e73 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -193,10 +193,8 @@ (map (fn [[x expr]] (let [[sql & params] (format-with-part x) [sql' & params'] (format-dsl expr)] - (cond-> [(str sql " AS " - (if (seq params') - (str "(" sql' ")") - sql'))] + ;; according to docs, CTE should _always_ be wrapped: + (cond-> [(str sql " AS " (str "(" sql' ")"))] params (into params) params' (into params')))) xs))] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 793e033..1dd95ad 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -84,9 +84,9 @@ :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"])) + ["WITH query AS (SELECT foo FROM bar)"])) (is (= (format {:with-recursive [[:query {:select [:foo] :from [:bar]}]]}) - ["WITH RECURSIVE query AS 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 From 5449c23edef86917aaceb7980e97b68fa6981edd Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 16:39:50 -0700 Subject: [PATCH 020/254] Clarify tests Annotate parameterizer tests as known failures. Create inline versions of :parameterizer :none tests. --- test/honey/sql_test.cljc | 67 ++++++++++++++++++++++++++++++---------- 1 file changed, 51 insertions(+), 16 deletions(-) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 1dd95ad..24e37c1 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -231,14 +231,14 @@ ["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" + (testing "array parameter -- fail: parameterizer" (is (= (format {:insert-into :foo :columns [:baz] :values [[[:array [1 2 3 4]]]]} {:parameterizer :none}) ["INSERT INTO foo (baz) VALUES (ARRAY[1, 2, 3, 4])"]))) - (testing "union complex values" + (testing "union complex values -- fail: parameterizer" (is (= (format {:union [{:select [:foo] :from [:bar1]} {:select [:foo] :from [:bar2]}] :with [[[:bar {:columns [:spam :eggs]}] @@ -246,26 +246,61 @@ {: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"])))) +(deftest inline-was-parameterizer-none + (testing "array parameter" + (is (= (format {:insert-into :foo + :columns [:baz] + :values [[[:array (mapv vector + (repeat :inline) + [1 2 3 4])]]]}) + ["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 (mapv #(mapv vector (repeat :inline) %) + [[1 2] [3 4] [5 6]])}]]}) + ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2"])))) #_(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"]))) +(deftest former-parameterizer-tests-where-and + (testing "should ignore a nil predicate -- fail: postgresql parameterizer" + (is (= (format {:where [:and + [:= :foo "foo"] + [:= :bar "bar"] + nil + [:= :quux "quux"]]} + {:parameterizer :postgresql}) + ["WHERE (foo = ?) AND (bar = $2) AND (quux = $3)" "foo" "bar" "quux"]))) + ;; this is _almost_ what :inline should be doing: + #_(testing "should fill param with single quote" + (is (= (format {:where [:and + [:= :foo "foo"] + [:= :bar "bar"] + nil + [:= :quux "quux"]]} + {:parameterizer :single-quote}) + ["WHERE (foo = 'foo') AND (bar = 'bar') AND (quux = 'quux')" "foo" "bar" "quux"]))) + (testing "should inline params with single quote" + (is (= (format {:where [:and + [:= :foo [:inline "foo"]] + [:= :bar [:inline "bar"]] + nil + [:= :quux [:inline "quux"]]]}) + ["WHERE (foo = 'foo') AND (bar = 'bar') AND (quux = 'quux')"]))) + ;; this is the normal behavior -- not a custom parameterizer! (testing "should fill param with ?" - (is (= (format {:where [:and [:= :foo "foo"] [:= :bar "bar"] nil]} - {:parameterizer :mysql-fill}) - ["WHERE (foo = ? AND bar = ?)" "foo" "bar"])))) - + (is (= (format {:where [:and + [:= :foo "foo"] + [:= :bar "bar"] + nil + [:= :quux "quux"]]} + ;; this never did anything useful: + #_{:parameterizer :mysql-fill}) + ["WHERE (foo = ?) AND (bar = ?) AND (quux = ?)" "foo" "bar" "quux"])))) (deftest set-before-from ; issue 235 (is (= From 0052aade7c9ff42dfc741be7e525e325996a2aba Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 16:40:15 -0700 Subject: [PATCH 021/254] Implement variadic and/or/+/* --- src/honey/sql.cljc | 58 +++++++++++++++++++++++++++------------- test/honey/sql_test.cljc | 2 ++ 2 files changed, 41 insertions(+), 19 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0dd9e73..1486441 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -458,27 +458,47 @@ (format-dsl x (assoc opts :nested? true)) (sequential? x) - (let [op (first x)] + (let [op (first x) + op-ignore-nil #{:and :or} + op-variadic #{:and :or :+ :*}] (if (keyword? op) (cond (infix-ops op) - (let [[_ a b] x - [s1 & p1] (format-expr a {:nested? true}) - [s2 & p2] (format-expr b {:nested? true}) - op (get infix-aliases op op)] - (if (and (#{:= :<>} op) (or (nil? a) (nil? b))) - (-> (str (if (nil? a) - (if (nil? b) "NULL" s2) - s1) - (if (= := op) " IS NULL" " IS NOT NULL")) - (cond-> nested? - (as-> s (str "(" s ")"))) - (vector)) - (-> (str s1 " " (sql-kw op) " " s2) - (cond-> nested? - (as-> s (str "(" s ")"))) - (vector) - (into p1) - (into p2)))) + (if (op-variadic op) ; no aliases here, no special semantics + (let [x (if (op-ignore-nil op) (remove nil? x) x) + [sqls params] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') + (if params' (into params params') params)]) + [[] []] + (map #(format-expr % {:nested? true}) + (rest x)))] + (into [(cond-> (str/join (str " " (sql-kw op) " ") sqls) + nested? + (as-> s (str "(" s ")")))] + params)) + (let [[_ a b & y] x + _ (when (seq y) + (throw (ex-info (str "only binary " + op + "is supported") + {:expr x}))) + [s1 & p1] (format-expr a {:nested? true}) + [s2 & p2] (format-expr b {:nested? true}) + op (get infix-aliases op op)] + (if (and (#{:= :<>} op) (or (nil? a) (nil? b))) + (-> (str (if (nil? a) + (if (nil? b) "NULL" s2) + s1) + (if (= := op) " IS NULL" " IS NOT NULL")) + (cond-> nested? + (as-> s (str "(" s ")"))) + (vector)) + (-> (str s1 " " (sql-kw op) " " s2) + (cond-> nested? + (as-> s (str "(" s ")"))) + (vector) + (into p1) + (into p2))))) (special-syntax op) (let [formatter (special-syntax op)] (formatter (rest x))) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 24e37c1..aa920e9 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -33,6 +33,8 @@ (sut/format-expr [:+ :id 1]))) (is (= ["? + (? + quux)" 1 1] (sut/format-expr [:+ 1 [:+ 1 :quux]]))) + (is (= ["? + ? + quux" 1 1] + (sut/format-expr [:+ 1 1 :quux]))) (is (= ["FOO(BAR(? + G(abc)), F(?, quux))" 2 1] (sut/format-expr [:foo [:bar [:+ 2 [:g :abc]]] [:f 1 :quux]]))) (is (= ["id"] From ae6229c282ce9a370ac954724add257a63166041 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 16:44:01 -0700 Subject: [PATCH 022/254] Move data_readers to test Since we will not need/support this in V2 --- {resources => test}/data_readers.clj | 0 1 file changed, 0 insertions(+), 0 deletions(-) rename {resources => test}/data_readers.clj (100%) diff --git a/resources/data_readers.clj b/test/data_readers.clj similarity index 100% rename from resources/data_readers.clj rename to test/data_readers.clj From 4d3b3175202e8e502b6f060c8cd2bdbd324fe5a0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 17:10:25 -0700 Subject: [PATCH 023/254] Add meta unwrap for more feature support --- src/honey/sql.cljc | 9 ++++++++- 1 file changed, 8 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1486441..a8019b5 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -528,6 +528,13 @@ {:valid-dialects (vec (sort (keys dialects)))}))) dialect) +(defn- unwrap [x opts] + (if-let [m (meta x)] + (if-let [f (::wrapper m)] + (f x opts) + x) + x)) + (defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." @@ -544,7 +551,7 @@ *quoted* (if (contains? opts :quoted) (:quoted opts) dialect?)] - (format-dsl data))))) + (mapv #(unwrap % opts) (format-dsl data)))))) (defn set-dialect! "Set the default dialect for formatting. From 6aced041790a5239ee01f1f017e210ef8987d32f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 25 Sep 2020 23:58:51 -0700 Subject: [PATCH 024/254] Address #266 by adding :pretty? true option Adds newline before, after, and between each SQL clause. --- README.md | 127 +++++++++++++++++++++++---------------------- src/honey/sql.cljc | 11 ++-- 2 files changed, 72 insertions(+), 66 deletions(-) diff --git a/README.md b/README.md index 3a1b611..5c7c44a 100644 --- a/README.md +++ b/README.md @@ -20,8 +20,6 @@ All sample code in this README is automatically run as a unit test using Note that while some of these samples show pretty-printed SQL, this is just for README readability; honeysql does not generate pretty-printed SQL. -_The `#sql/regularize` directive tells the test-runner to ignore the extraneous whitespace._ [TODO: replace with pretty print option!] - ## Usage ```clojure @@ -147,11 +145,12 @@ then provide a collection of rows, each a collection of column values: [["Jon" "Smith" 34] ["Andrew" "Cooper" 12] ["Jane" "Daniels" 56]]) - sql/format) -=> [#sql/regularize - "INSERT INTO properties (name, surname, age) - VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" - "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] + (sql/format {:pretty? true})) +=> [" +INSERT INTO properties (name, surname, age) +VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] ``` @@ -163,13 +162,14 @@ and the remaining maps *must* have the same set of keys and values: (values [{:name "John" :surname "Smith" :age 34} {:name "Andrew" :surname "Cooper" :age 12} {:name "Jane" :surname "Daniels" :age 56}]) - sql/format) -=> [#sql/regularize - "INSERT INTO properties (name, surname, age) - VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" - "John" "Smith" 34 - "Andrew" "Cooper" 12 - "Jane" "Daniels" 56] + (sql/format {:pretty? true})) +=> [" +INSERT INTO properties (name, surname, age) +VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"John" "Smith" 34 +"Andrew" "Cooper" 12 +"Jane" "Daniels" 56] ``` ### Nested subqueries @@ -184,13 +184,14 @@ The column values do not have to be literals, they can be nested queries: :role_id (-> (select :id) (from :role) (where [:= :name role-name]))}]) - sql/format)) + (sql/format {:pretty? true}))) -=> [#sql/regularize - "INSERT INTO user_profile_to_role (user_profile_id, role_id) - VALUES (?, (SELECT id FROM role WHERE name = ?))" - 12345 - "user"] +=> [" +INSERT INTO user_profile_to_role (user_profile_id, role_id) +VALUES (?, (SELECT id FROM role WHERE name = ?)) +" +12345 +"user"] ``` ```clojure @@ -211,11 +212,12 @@ Composite types are supported: (values [["small" (composite 1 "inch")] ["large" (composite 10 "feet")]]) - sql/format) -=> [#sql/regularize - "INSERT INTO comp_table (name, comp_column) - VALUES (?, (?, ?)), (?, (?, ?))" - "small" 1 "inch" "large" 10 "feet"] + (sql/format {:pretty? true})) +=> [" +INSERT INTO comp_table (name, comp_column) +VALUES (?, (?, ?)), (?, (?, ?)) +" +"small" 1 "inch" "large" 10 "feet"] ``` ### Updates @@ -228,13 +230,14 @@ with `clojure.core/set`): (sset {:kind "dramatic" :watched (sql/call :+ :watched 1)}) (where [:= :kind "drama"]) - sql/format) -=> [#sql/regularize - "UPDATE films SET kind = ?, watched = (watched + ?) - WHERE kind = ?" - "dramatic" - 1 - "drama"] + (sql/format {:pretty? true})) +=> [" +UPDATE films SET kind = ?, watched = (watched + ?) +WHERE kind = ? +" +"dramatic" +1 +"drama"] ``` If you are trying to build a compound update statement (with `from` or `join`), @@ -251,7 +254,7 @@ Deletes look as you would expect: ```clojure (-> (delete-from :films) (where [:<> :kind "musical"]) - sql/format) + (sql/format)) => ["DELETE FROM films WHERE kind <> ?" "musical"] ``` @@ -262,20 +265,21 @@ If your database supports it, you can also delete from multiple tables: (from :films) (join :directors [:= :films.director_id :directors.id]) (where [:<> :kind "musical"]) - sql/format) -=> [#sql/regularize - "DELETE films, directors - FROM films - INNER JOIN directors ON films.director_id = directors.id - WHERE kind <> ?" - "musical"] + (sql/format {:pretty? true})) +=> [" +DELETE films, directors +FROM films +INNER JOIN directors ON films.director_id = directors.id +WHERE kind <> ? +" +"musical"] ``` If you want to delete everything from a table, you can use `truncate`: ```clojure (-> (truncate :films) - sql/format) + (sql/format)) => ["TRUNCATE films"] ``` @@ -348,11 +352,12 @@ have a lot of function calls needed in code: (values [{:location [:ST_SetSRID [:ST_MakePoint 0.291 32.621] [:cast 4325 :integer]]}]) - (sql/format)) -=> [#sql/regularize - "INSERT INTO sample (location) - VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer)))" - 0.291 32.621 4326] + (sql/format {:pretty? true})) +=> [" +INSERT INTO sample (location) +VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) +" +0.291 32.621 4326] ``` #### Raw SQL fragments @@ -477,22 +482,20 @@ big-complicated-map ``` ```clojure (sql/format big-complicated-map {:param1 "gabba" :param2 2}) -=> [#sql/regularize - "SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 - FROM foo f, baz b - INNER JOIN draq ON f.b = draq.x - LEFT JOIN clod c ON f.a = c.d - RIGHT JOIN bock ON bock.z = c.e - WHERE ((f.a = ? AND b.baz <> ?) - OR (? < ? AND ? < ?) - OR (f.e in (?, ?, ?)) - OR f.e BETWEEN ? AND ?) - GROUP BY f.a, c.e - HAVING ? < f.e - ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST - LIMIT ? - OFFSET ? " - "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] +=> [" +SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 +FROM foo f, baz b +INNER JOIN draq ON f.b = draq.x +LEFT JOIN clod c ON f.a = c.d +RIGHT JOIN bock ON bock.z = c.e +WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) +GROUP BY f.a, c.e +HAVING ? < f.e +ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST +LIMIT ? +OFFSET ? +" +"bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ``` ```clojure ;; Printable and readable diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a8019b5..639f18f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -374,7 +374,7 @@ ;:values 220 :query-values 230}) -(defn- format-dsl [x & [{:keys [aliased? nested?]}]] +(defn- format-dsl [x & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] (if-let [xs (k x)] @@ -395,7 +395,9 @@ (str/join ", " (keys leftover))) leftover)) [(str "")]) - (into [(cond-> (str/join " " sqls) + (into [(cond-> (str/join (if pretty? "\n" " ") sqls) + pretty? + (as-> s (str "\n" s "\n")) (and nested? (not aliased?)) (as-> s (str "(" s ")")))] params)))) @@ -551,7 +553,7 @@ *quoted* (if (contains? opts :quoted) (:quoted opts) dialect?)] - (mapv #(unwrap % opts) (format-dsl data)))))) + (mapv #(unwrap % opts) (format-dsl data opts)))))) (defn set-dialect! "Set the default dialect for formatting. @@ -603,9 +605,10 @@ (format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}) (format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}) (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) + (println (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {:pretty? true})) (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) (format {:select [:*] :from [:table] :where [:= :id (int 1)]} {:dialect :mysql}) (map fn? (format {:select [:*] :from [:table] :where [:= :id (with-meta (constantly 42) {:foo true})]} {:dialect :mysql})) - (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {}) + (println (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {:pretty? true})) ,) From 002523bb8cf6b98e36c923ac422b59938e97bbdb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 26 Sep 2020 00:17:31 -0700 Subject: [PATCH 025/254] Generate AS for select/from; except for Oracle --- src/honey/sql.cljc | 15 ++++++++++----- test/honey/sql_test.cljc | 26 +++++++++++++++++++------- 2 files changed, 29 insertions(+), 12 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 639f18f..9300c93 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -46,7 +46,7 @@ (filterv (complement #{:set}) %) :set :where)} - :oracle {:quote #(str \" % \")}}) + :oracle {:quote #(str \" % \") :as false}}) ; should become defonce (def ^:private default-dialect (atom (:ansi dialects))) @@ -109,7 +109,7 @@ {:selectable s}))) (cond-> (format-entity s) pair? - (str #_" AS " " " + (str (if (and (contains? *dialect* :as) (not (:as *dialect*))) " " " AS ") (format-entity (second x) {:aliased? true})))) :else @@ -133,7 +133,12 @@ (format-selectable-dsl a {:aliased? true})))] (-> [(cond-> sql pair? - (str (if as? " AS " " ") sql'))] + (str (if as? + (if (and (contains? *dialect* :as) + (not (:as *dialect*))) + " " + " AS ") + " ") sql'))] (into params) (into params'))) @@ -172,9 +177,9 @@ (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-selectable-dsl % {:as? (= k :select)}) xs))] + (map #(format-selectable-dsl % {:as? (#{:select :from} k)}) xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) - (let [[sql & params] (format-selectable-dsl xs {:as? (= k :select)})] + (let [[sql & params] (format-selectable-dsl xs {:as? (#{:select :from} k)})] (into [(str (sql-kw k) " " sql)] params)))) (defn- format-with-part [x] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index aa920e9..e39f323 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -52,7 +52,7 @@ (is (= ["SELECT * FROM \"table\" 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] + (is (= ["SELECT \"t\".* FROM \"table\" AS \"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]} {:quoted true}))) @@ -69,8 +69,20 @@ (is (= ["SELECT * FROM \"table\" WHERE \"id\" IN (?, ?, ?, ?)" 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 +;; issue-based tests +(deftest subquery-alias-263 + (is (= ["SELECT type FROM (SELECT address AS field-alias FROM Candidate) AS sub-q-alias"] + (sut/format {:select [:type] + :from [[{:select [[:address :field-alias]] + :from [:Candidate]} :sub-q-alias]]}))) + (is (= ["SELECT type FROM (SELECT address field-alias FROM Candidate) sub-q-alias"] + (sut/format {:select [:type] + :from [[{:select [[:address :field-alias]] + :from [:Candidate]} :sub-q-alias]]} + {:dialect :oracle :quoted false})))) + +;; 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`"] @@ -81,7 +93,7 @@ "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] + (is (= ["SELECT vals.a FROM (VALUES (?, ?, ?)) AS vals (a, b, c)" 1 2 3] (format {:select [:vals.a] :from [[{:values [[1 2 3]]} [:vals {:columns [:a :b :c]}]]]})))) (deftest test-cte @@ -306,7 +318,7 @@ (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\" SET \"kind\" = \"c\".\"test\" FROM (SELECT \"b\".\"test\" FROM \"bar\" AS \"b\" WHERE \"b\".\"id\" = ?) AS \"c\" WHERE \"f\".\"kind\" = ?" 1 "drama"] (-> {:update [:films :f] :set {:kind :c.test} @@ -333,7 +345,7 @@ (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] + (is (= ["DELETE `t1`, `t2` FROM `table1` AS `t1` INNER JOIN `table2` AS `t2` ON `t1`.`fk` = `t2`.`id` WHERE `t1`.`bar` = ?" 42] (-> {:delete [:t1 :t2] :from [[:table1 :t1]] :join [[:table2 :t2] [:= :t1.fk :t2.id]] @@ -372,7 +384,7 @@ (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"] + (is (= ["SELECT foo FROM bar INNER JOIN table AS t ON TRUE"] (format {:select [:foo] :from [:bar] :join [[:table :t] true]})))) @@ -382,7 +394,7 @@ (format {:select [:*] :from [:foo] :cross-join [:bar]}))) - (is (= ["SELECT * FROM foo f CROSS JOIN bar b"] + (is (= ["SELECT * FROM foo AS f CROSS JOIN bar b"] (format {:select [:*] :from [[:foo :f]] :cross-join [[:bar :b]]})))) From 9154d736783d0ca976ec7965040c05dc268fdd39 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 26 Sep 2020 00:39:54 -0700 Subject: [PATCH 026/254] Implement returning (postgres) --- src/honey/sql.cljc | 11 +++++++++-- 1 file changed, 9 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 9300c93..17f21b9 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -20,7 +20,8 @@ :columns :set :from :join :left-join :right-join :inner-join :outer-join :full-join :cross-join - :where :group-by :having :order-by :limit :offset :values]) + :where :group-by :having :order-by :limit :offset :values + :returning]) (defn- add-clause-before "Low-level helper just to insert a new clause." @@ -339,7 +340,8 @@ :order-by #'format-order-by :limit #'format-on-expr :offset #'format-on-expr - :values #'format-values})) + :values #'format-values + :returning #'format-selects})) (assert (= (set @base-clause-order) (set @current-clause-order) @@ -378,6 +380,11 @@ :lock 215 ;:values 220 :query-values 230}) +;; :on-conflict -- https://www.postgresqltutorial.com/postgresql-upsert/ +;; :on-constraint (part of :on-conflict) +;; :do-update-set +;; ;do-nothing + ;:returning (defn- format-dsl [x & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] From 25097af134e9c441076a295b98054c154f53af7e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 26 Sep 2020 15:16:12 -0700 Subject: [PATCH 027/254] First cut of on conflict support --- src/honey/sql.cljc | 18 ++++++++++++++++++ test/honey/sql_test.cljc | 4 ++++ 2 files changed, 22 insertions(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 17f21b9..4a0ed91 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -21,6 +21,7 @@ :join :left-join :right-join :inner-join :outer-join :full-join :cross-join :where :group-by :having :order-by :limit :offset :values + :on-conflict :on-constraint :do-nothing :do-update-set :returning]) (defn- add-clause-before @@ -297,6 +298,19 @@ xs)] (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) +(defn- format-on-conflict [k x] + (if (keyword? x) + [(str (sql-kw k) " (" (format-entity x) ")")] + (let [[sql & params] (format-dsl x)] + (into [(str (sql-kw k) " " sql)] params)))) + +(defn- format-do-update-set [k x] + (if (keyword? x) + (let [e (format-entity x {:drop-ns? true})] + [(str (sql-kw k) " " e " = EXCLUDED." e)]) + (let [[sql & params] (format-set-exprs :set x)] + (into [(str (sql-kw k) " " sql)] params)))) + (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. @@ -341,6 +355,10 @@ :limit #'format-on-expr :offset #'format-on-expr :values #'format-values + :on-conflict #'format-on-conflict + :on-constraint #'format-selector + :do-nothing (fn [k _] (vector (sql-kw k))) + :do-update-set #'format-do-update-set :returning #'format-selects})) (assert (= (set @base-clause-order) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index e39f323..1401019 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -398,3 +398,7 @@ (format {:select [:*] :from [[:foo :f]] :cross-join [[:bar :b]]})))) + +(comment ; make on conflict tests, based on nilenso repo and PG docs + (format {:insert-into :foo, :values [[1 2 3]], :on-conflict :e :do-nothing true}) + (format {:insert-into :foo, :values [[1 2 3]], :on-conflict {:on-constraint :foo_key} :do-update-set {:a 42 :b :excluded.b}})) From 61cf6eda5a4bfe05f548c90153fe0de50bb10209 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 11:49:13 -0700 Subject: [PATCH 028/254] Add variadic string concatenation || --- src/honey/sql.cljc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4a0ed91..1e30c26 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -440,7 +440,7 @@ :regex :regexp}) (def ^:private infix-ops - (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" + (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "in" "not-in" "like" "not-like" "regexp" "is" "is-not" "not=" "!=" "regex"} (into (map str "+-*/%|&^=<>")) @@ -492,7 +492,7 @@ (sequential? x) (let [op (first x) op-ignore-nil #{:and :or} - op-variadic #{:and :or :+ :*}] + op-variadic #{:and :or :+ :* :||}] (if (keyword? op) (cond (infix-ops op) (if (op-variadic op) ; no aliases here, no special semantics From 6db2426046f1003a2f7b00b38654447f8dcd63f0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 11:49:29 -0700 Subject: [PATCH 029/254] Fix do update set; add on conflict tests --- src/honey/sql.cljc | 3 +-- test/honey/sql_test.cljc | 44 +++++++++++++++++++++++++++++++++++++--- 2 files changed, 42 insertions(+), 5 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1e30c26..dbe29f3 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -308,8 +308,7 @@ (if (keyword? x) (let [e (format-entity x {:drop-ns? true})] [(str (sql-kw k) " " e " = EXCLUDED." e)]) - (let [[sql & params] (format-set-exprs :set x)] - (into [(str (sql-kw k) " " sql)] params)))) + (format-set-exprs k x))) (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 1401019..fe741d0 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -399,6 +399,44 @@ :from [[:foo :f]] :cross-join [[:bar :b]]})))) -(comment ; make on conflict tests, based on nilenso repo and PG docs - (format {:insert-into :foo, :values [[1 2 3]], :on-conflict :e :do-nothing true}) - (format {:insert-into :foo, :values [[1 2 3]], :on-conflict {:on-constraint :foo_key} :do-update-set {:a 42 :b :excluded.b}})) +(deftest on-conflict-tests + ;; these examples are taken from https://www.postgresqltutorial.com/postgresql-upsert/ + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT ON CONSTRAINT customers_name_key +DO NOTHING +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict {:on-constraint :customers_name_key} + :do-nothing true} + {:pretty? true}))) + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT (name) +DO NOTHING +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict :name + :do-nothing true} + {:pretty? true}))) + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT (name) +DO UPDATE SET email = EXCLUDED.email || ';' || customers.email +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict :name + :do-update-set {:email [:|| :EXCLUDED.email [:inline ";"] :customers.email]}} + {:pretty? true})))) From 804305d3c5162c484cd3a3b2b803238535258bd7 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 11:52:32 -0700 Subject: [PATCH 030/254] Add EXCEPT ALL --- src/honey/sql.cljc | 1 + 1 file changed, 1 insertion(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index dbe29f3..b7019ee 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -331,6 +331,7 @@ :union #'format-on-set-op :union-all #'format-on-set-op :except #'format-on-set-op + :except-all #'format-on-set-op :select #'format-selects :insert-into #'format-insert :update #'format-selector From ad49c4e3860dde442c3b8f6ca03a634d629cdab6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 12:12:10 -0700 Subject: [PATCH 031/254] Add NOT operator, improve NULL support --- src/honey/sql.cljc | 9 ++++++++- 1 file changed, 8 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b7019ee..14c563d 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -480,7 +480,11 @@ :interval (fn [[n units]] (let [[sql & params] (format-expr n)] - (into [(str "INTERVAL " sql " " (sql-kw units))] params)))}) + (into [(str "INTERVAL " sql " " (sql-kw units))] params))) + :not + (fn [[x]] + (let [[sql & params] (format-expr x)] + (into [(str "NOT " sql)] params)))}) (defn format-expr [x & [{:keys [nested?] :as opts}]] (cond (or (keyword? x) (symbol? x)) @@ -551,6 +555,9 @@ (or (true? x) (false? x)) ; because (boolean? x) requires Clojure 1.9+ [(upper-case (str x))] + (nil? x) + ["NULL"] + :else ["?" x])) From 534401e5d6d18d59f2ed1f8f23b97e7512f7d831 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 12:12:25 -0700 Subject: [PATCH 032/254] Add ILIKE/NOT-ILIKE --- src/honey/sql.cljc | 1 + 1 file changed, 1 insertion(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 14c563d..088b078 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -442,6 +442,7 @@ (def ^:private infix-ops (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "in" "not-in" "like" "not-like" "regexp" + "ilike" "not-ilike" "is" "is-not" "not=" "!=" "regex"} (into (map str "+-*/%|&^=<>")) (into (keys infix-aliases)) From 0706d0b7baf12cecbd2c30dffdc23a0346e87321 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 12:12:40 -0700 Subject: [PATCH 033/254] Improve insert into support --- src/honey/sql.cljc | 35 ++++++++++++++++++----------------- 1 file changed, 18 insertions(+), 17 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 088b078..9ccff73 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -15,7 +15,7 @@ (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." - [:with :with-recursive :intersect :union :union-all :except + [:with :with-recursive :intersect :union :union-all :except :except-all :select :insert-into :update :delete :delete-from :truncate :columns :set :from :join :left-join :right-join :inner-join :outer-join :full-join @@ -211,23 +211,24 @@ (format-selects k [xs])) (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-entity-alias table) - " (" - (str/join ", " (map #'format-entity-alias cols)) - ") " - sql)] - params)) - (let [[table statement] table - [sql & params] (format-dsl statement)] - (into [(str (sql-kw k) " " (format-entity-alias table) - " " sql)] - params))) + (cond (sequential? (first table)) + (let [[[table cols] statement] table + [sql & params] (format-dsl statement)] + (into [(str (sql-kw k) " " (format-entity-alias table) + " (" + (str/join ", " (map #'format-entity-alias cols)) + ") " + sql)] + params)) + (map? (second table)) + (let [[table statement] table + [sql & params] (format-dsl statement)] + (into [(str (sql-kw k) " " (format-entity-alias table) + " " sql)] + params)) + :else + [(str (sql-kw k) " " (format-entity-alias table))]) [(str (sql-kw k) " " (format-entity-alias table))])) (defn- format-join [k [j e]] From a7590e9216b46b7e7105fab58ea7be73aa027f78 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 13:18:21 -0700 Subject: [PATCH 034/254] Enhance special syntax Pass op in as first argument so we can write more generic functions. --- src/honey/sql.cljc | 17 ++++++++++------- 1 file changed, 10 insertions(+), 7 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 9ccff73..f53c700 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -460,11 +460,11 @@ (def ^:private special-syntax {:array - (fn [[arr]] + (fn [k [arr]] (let [[sqls params] (format-expr-list arr)] (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) :between - (fn [[x a b]] + (fn [k [x a b]] (let [[sql-x & params-x] (format-expr x {:nested? true}) [sql-a & params-a] (format-expr a {:nested? true}) [sql-b & params-b] (format-expr b {:nested? true})] @@ -473,18 +473,21 @@ (into params-a) (into params-b)))) :cast - (fn [[x type]] + (fn [k [x type]] (let [[sql & params] (format-expr x)] (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) + :default + (fn [k []] + ["DEFAULT"]) :inline - (fn [[x]] + (fn [k [x]] [(sqlize-value x)]) :interval - (fn [[n units]] + (fn [k [n units]] (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params))) :not - (fn [[x]] + (fn [k [x]] (let [[sql & params] (format-expr x)] (into [(str "NOT " sql)] params)))}) @@ -539,7 +542,7 @@ (into p2))))) (special-syntax op) (let [formatter (special-syntax op)] - (formatter (rest x))) + (formatter op (rest x))) :else (let [args (rest x) [sqls params] (format-expr-list args)] From 1fdd50d6b01ca69c4de2cc7d98bb1cd776612a8a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 13:18:34 -0700 Subject: [PATCH 035/254] Add more tests on insert --- test/honey/sql_test.cljc | 49 +++++++++++++++++++++++++++++++++++++++- 1 file changed, 48 insertions(+), 1 deletion(-) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index fe741d0..8071fb1 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -215,6 +215,10 @@ :from [:bar] :where [:= [:mod :col1 4] [:+ :col2 4]]})))) + (testing "Example from dharrigan" + (is (= ["SELECT pg_try_advisory_lock(1)"] + (format {:select [:%pg_try_advisory_lock.1]})))) + (testing "Value context only applies to sequences in value/comparison spots" (let [sub {:select [:%sum.amount] :from [:bar] @@ -236,7 +240,6 @@ {: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]}] @@ -399,6 +402,50 @@ :from [[:foo :f]] :cross-join [[:bar :b]]})))) +(deftest insert-example-tests + ;; these examples are taken from https://www.postgresql.org/docs/13/sql-insert.html + (is (= [" +INSERT INTO films +VALUES ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes') +"] + (format {:insert-into :films + :values [[[:inline "UA502"] [:inline "Bananas"] [:inline 105] + [:inline "1971-07-13"] [:inline "Comedy"] + [:inline "82 minutes"]]]} + {:pretty? true}))) + (is (= [" +INSERT INTO films +VALUES (?, ?, ?, ?, ?, ?) +" "UA502", "Bananas", 105, "1971-07-13", "Comedy", "82 minutes"] + (format {:insert-into :films + :values [["UA502" "Bananas" 105 "1971-07-13" "Comedy" "82 minutes"]]} + {:pretty? true}))) + (is (= [" +INSERT INTO films +(code, title, did, date_prod, kind) +VALUES (?, ?, ?, ?, ?) +" "T_601", "Yojimo", 106, "1961-06-16", "Drama"] + (format {:insert-into :films + :columns [:code :title :did :date_prod :kind] + :values [["T_601", "Yojimo", 106, "1961-06-16", "Drama"]]} + {:pretty? true}))) + (is (= [" +INSERT INTO films +VALUES (?, ?, ?, DEFAULT, ?, ?) +" "UA502", "Bananas", 105, "Comedy", "82 minutes"] + (format {:insert-into :films + :values [["UA502" "Bananas" 105 [:default] "Comedy" "82 minutes"]]} + {:pretty? true}))) + (is (= [" +INSERT INTO films +(code, title, did, date_prod, kind) +VALUES (?, ?, ?, DEFAULT, ?) +" "T_601", "Yojimo", 106, "Drama"] + (format {:insert-into :films + :columns [:code :title :did :date_prod :kind] + :values [["T_601", "Yojimo", 106, [:default], "Drama"]]} + {:pretty? true})))) + (deftest on-conflict-tests ;; these examples are taken from https://www.postgresqltutorial.com/postgresql-upsert/ (is (= [" From 6d31c4839d1fb4d939c4bd1aa034d88b3864ab0c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 13:47:55 -0700 Subject: [PATCH 036/254] Add first pass of helpers --- src/honey/sql/helpers.clj | 6 -- src/honey/sql/helpers.cljc | 67 ++++++++++++ src/readme.clj | 209 +++++++++++++++++++------------------ 3 files changed, 173 insertions(+), 109 deletions(-) delete mode 100644 src/honey/sql/helpers.clj create mode 100644 src/honey/sql/helpers.cljc diff --git a/src/honey/sql/helpers.clj b/src/honey/sql/helpers.clj deleted file mode 100644 index 0363db8..0000000 --- a/src/honey/sql/helpers.clj +++ /dev/null @@ -1,6 +0,0 @@ -;; copyright (c) 2020 sean corfield, all rights reserved - -(ns honey.sql.helpers - "Macros to create consistent helpers from DSL clauses. - - I don't know how this will work in ClojureScript yet...") diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc new file mode 100644 index 0000000..e147cc2 --- /dev/null +++ b/src/honey/sql/helpers.cljc @@ -0,0 +1,67 @@ +;; copyright (c) 2020 sean corfield, all rights reserved + +(ns honey.sql.helpers + "Helper functions for the built-in clauses in honey.sql." + (:refer-clojure :exclude [update set group-by]) + (:require [honey.sql :as h])) + +(defn- default-merge [current args] + (into (vec current) args)) + +(def ^:private special-merges + {:where (fn [current args] + (if (= :and (first (first args))) + (default-merge current args) + (-> [:and] + (into current) + (into args))))}) + +(defn- helper-merge [data k args] + (let [merge-fn (special-merges k default-merge)] + (clojure.core/update data k merge-fn args))) + +(defn- generic [k args] + (if (map? (first args)) + (let [[data & args] args] + (helper-merge data k args)) + (helper-merge {} k args))) + +(defn with [& args] (generic :with args)) +(defn with-recursive [& args] (generic :with-recursive args)) +(defn intersect [& args] (generic :intersect args)) +(defn union [& args] (generic :union args)) +(defn union-all [& args] (generic :union-all args)) +(defn except [& args] (generic :except args)) +(defn except-all [& args] (generic :except-all args)) +(defn select [& args] (generic :select args)) +(defn insert-into [& args] (generic :insert-into args)) +(defn update [& args] (generic :update args)) +(defn delete [& args] (generic :delete args)) +(defn delete-from [& args] (generic :delete-from args)) +(defn truncate [& args] (generic :truncate args)) +(defn columns [& args] (generic :columns args)) +(defn set [& args] (generic :set args)) +(defn from [& args] (generic :from args)) +(defn join [& args] (generic :join args)) +(defn left-join [& args] (generic :left-join args)) +(defn right-join [& args] (generic :right-join args)) +(defn inner-join [& args] (generic :inner-join args)) +(defn outer-join [& args] (generic :outer-join args)) +(defn full-join [& args] (generic :full-join args)) +(defn cross-join [& args] (generic :cross-join args)) +(defn where [& args] (generic :where args)) +(defn group-by [& args] (generic :group-by args)) +(defn having [& args] (generic :having args)) +(defn order-by [& args] (generic :order-by args)) +(defn limit [& args] (generic :limit args)) +(defn offset [& args] (generic :offset args)) +(defn values [& args] (generic :values args)) +(defn on-conflict [& args] (generic :on-conflict args)) +(defn on-constraint [& args] (generic :on-constraint args)) +(defn do-nothing [& args] (generic :do-nothing args)) +(defn do-update-set [& args] (generic :do-update-set args)) +(defn returning [& args] (generic :returning args)) + +#?(:clj + (assert (= (clojure.core/set @@#'h/base-clause-order) + (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) diff --git a/src/readme.clj b/src/readme.clj index d6f4b75..b996a51 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -22,16 +22,14 @@ - - -(seancorfield.readme/defreadme readme-27 +(seancorfield.readme/defreadme readme-25 (require '[honey.sql :as sql] '[honey.sql.helpers :refer :all :as helpers]) ) -(seancorfield.readme/defreadme readme-34 +(seancorfield.readme/defreadme readme-32 (def sqlmap {:select [:a :b :c] :from [:foo] :where [:= :f.a "baz"]}) @@ -43,7 +41,7 @@ -(seancorfield.readme/defreadme readme-46 +(seancorfield.readme/defreadme readme-44 (sql/format sqlmap) => ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] ) @@ -64,7 +62,7 @@ -(seancorfield.readme/defreadme readme-67 +(seancorfield.readme/defreadme readme-65 (def q-sqlmap {:select [:foo/a :foo/b :foo/c] :from [:foo] :where [:= :foo/a "baz"]}) @@ -78,7 +76,7 @@ -(seancorfield.readme/defreadme readme-81 +(seancorfield.readme/defreadme readme-79 (-> (select :a :b :c) (from :foo) (where [:= :f.a "baz"])) @@ -86,7 +84,7 @@ -(seancorfield.readme/defreadme readme-89 +(seancorfield.readme/defreadme readme-87 (= (-> (select :*) (from :foo)) (-> (from :foo) (select :*))) => true @@ -94,14 +92,14 @@ -(seancorfield.readme/defreadme readme-97 +(seancorfield.readme/defreadme readme-95 (-> sqlmap (select :d)) => '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} ) -(seancorfield.readme/defreadme readme-104 +(seancorfield.readme/defreadme readme-102 (-> sqlmap (dissoc :select) (select :*) @@ -112,7 +110,7 @@ -(seancorfield.readme/defreadme readme-115 +(seancorfield.readme/defreadme readme-113 (-> (select :*) (from :foo) (where [:= :a 1] [:< :b 100]) @@ -123,7 +121,7 @@ -(seancorfield.readme/defreadme readme-126 +(seancorfield.readme/defreadme readme-124 (-> (select :a [:b :bar] :c [:d :x]) (from [:foo :quux]) (where [:= :quux.a 1] [:< :bar 100]) @@ -140,36 +138,38 @@ -(seancorfield.readme/defreadme readme-143 +(seancorfield.readme/defreadme readme-141 (-> (insert-into :properties) (columns :name :surname :age) (values [["Jon" "Smith" 34] ["Andrew" "Cooper" 12] ["Jane" "Daniels" 56]]) - sql/format) -=> [#sql/regularize - "INSERT INTO properties (name, surname, age) - VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" - "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] + (sql/format {:pretty? true})) +=> [" +INSERT INTO properties (name, surname, age) +VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] ) -(seancorfield.readme/defreadme readme-161 +(seancorfield.readme/defreadme readme-160 (-> (insert-into :properties) (values [{:name "John" :surname "Smith" :age 34} {:name "Andrew" :surname "Cooper" :age 12} {:name "Jane" :surname "Daniels" :age 56}]) - sql/format) -=> [#sql/regularize - "INSERT INTO properties (name, surname, age) - VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)" - "John" "Smith" 34 - "Andrew" "Cooper" 12 - "Jane" "Daniels" 56] + (sql/format {:pretty? true})) +=> [" +INSERT INTO properties (name, surname, age) +VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"John" "Smith" 34 +"Andrew" "Cooper" 12 +"Jane" "Daniels" 56] ) @@ -184,16 +184,17 @@ :role_id (-> (select :id) (from :role) (where [:= :name role-name]))}]) - sql/format)) + (sql/format {:pretty? true}))) -=> [#sql/regularize - "INSERT INTO user_profile_to_role (user_profile_id, role_id) - VALUES (?, (SELECT id FROM role WHERE name = ?))" - 12345 - "user"] +=> [" +INSERT INTO user_profile_to_role (user_profile_id, role_id) +VALUES (?, (SELECT id FROM role WHERE name = ?)) +" +12345 +"user"] ) -(seancorfield.readme/defreadme readme-196 +(seancorfield.readme/defreadme readme-197 (-> (select :*) (from :foo) (where [:in :foo.a (-> (select :a) (from :bar))]) @@ -205,17 +206,18 @@ -(seancorfield.readme/defreadme readme-208 +(seancorfield.readme/defreadme readme-209 (-> (insert-into :comp_table) (columns :name :comp_column) (values [["small" (composite 1 "inch")] ["large" (composite 10 "feet")]]) - sql/format) -=> [#sql/regularize - "INSERT INTO comp_table (name, comp_column) - VALUES (?, (?, ?)), (?, (?, ?))" - "small" 1 "inch" "large" 10 "feet"] + (sql/format {:pretty? true})) +=> [" +INSERT INTO comp_table (name, comp_column) +VALUES (?, (?, ?)), (?, (?, ?)) +" +"small" 1 "inch" "large" 10 "feet"] ) @@ -223,18 +225,19 @@ -(seancorfield.readme/defreadme readme-226 +(seancorfield.readme/defreadme readme-228 (-> (helpers/update :films) (sset {:kind "dramatic" :watched (sql/call :+ :watched 1)}) (where [:= :kind "drama"]) - sql/format) -=> [#sql/regularize - "UPDATE films SET kind = ?, watched = (watched + ?) - WHERE kind = ?" - "dramatic" - 1 - "drama"] + (sql/format {:pretty? true})) +=> [" +UPDATE films SET kind = ?, watched = (watched + ?) +WHERE kind = ? +" +"dramatic" +1 +"drama"] ) @@ -248,34 +251,35 @@ -(seancorfield.readme/defreadme readme-251 +(seancorfield.readme/defreadme readme-254 (-> (delete-from :films) (where [:<> :kind "musical"]) - sql/format) + (sql/format)) => ["DELETE FROM films WHERE kind <> ?" "musical"] ) -(seancorfield.readme/defreadme readme-260 +(seancorfield.readme/defreadme readme-263 (-> (delete [:films :directors]) (from :films) (join :directors [:= :films.director_id :directors.id]) (where [:<> :kind "musical"]) - sql/format) -=> [#sql/regularize - "DELETE films, directors - FROM films - INNER JOIN directors ON films.director_id = directors.id - WHERE kind <> ?" - "musical"] + (sql/format {:pretty? true})) +=> [" +DELETE films, directors +FROM films +INNER JOIN directors ON films.director_id = directors.id +WHERE kind <> ? +" +"musical"] ) -(seancorfield.readme/defreadme readme-276 +(seancorfield.readme/defreadme readme-280 (-> (truncate :films) - sql/format) + (sql/format)) => ["TRUNCATE films"] ) @@ -283,7 +287,7 @@ -(seancorfield.readme/defreadme readme-286 +(seancorfield.readme/defreadme readme-290 (sql/format {:union [(-> (select :*) (from :foo)) (-> (select :*) (from :bar))]}) => ["SELECT * FROM foo UNION SELECT * FROM bar"] @@ -293,11 +297,11 @@ -(seancorfield.readme/defreadme readme-296 +(seancorfield.readme/defreadme readme-300 (-> (select :%count.*) (from :foo) sql/format) => ["SELECT count(*) FROM foo"] ) -(seancorfield.readme/defreadme readme-300 +(seancorfield.readme/defreadme readme-304 (-> (select :%max.id) (from :foo) sql/format) => ["SELECT max(id) FROM foo"] ) @@ -308,7 +312,7 @@ -(seancorfield.readme/defreadme readme-311 +(seancorfield.readme/defreadme readme-315 (-> (select :id) (from :foo) (where [:= :a :?baz]) @@ -321,19 +325,19 @@ -(seancorfield.readme/defreadme readme-324 +(seancorfield.readme/defreadme readme-328 (def call-qualify-map (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) (where [:= :a (???/param :baz)] [:= :b [:inline 42]]))) ) -(seancorfield.readme/defreadme readme-330 +(seancorfield.readme/defreadme readme-334 call-qualify-map => '{:where [:and [:= :a ???/param :baz] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ) -(seancorfield.readme/defreadme readme-336 +(seancorfield.readme/defreadme readme-340 (sql/format call-qualify-map :??? {:baz "BAZ"}) => ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ) @@ -343,16 +347,17 @@ call-qualify-map -(seancorfield.readme/defreadme readme-346 +(seancorfield.readme/defreadme readme-350 (-> (insert-into :sample) (values [{:location [:ST_SetSRID [:ST_MakePoint 0.291 32.621] [:cast 4325 :integer]]}]) - (sql/format)) -=> [#sql/regularize - "INSERT INTO sample (location) - VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer)))" - 0.291 32.621 4326] + (sql/format {:pretty? true})) +=> [" +INSERT INTO sample (location) +VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) +" +0.291 32.621 4326] ) @@ -368,7 +373,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-371 +(seancorfield.readme/defreadme readme-376 (-> (select :*) (from :foo) (where [:< :expired_at (sql/raw ["now() - '" 5 " seconds'"])]) @@ -376,7 +381,7 @@ call-qualify-map => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ) -(seancorfield.readme/defreadme readme-379 +(seancorfield.readme/defreadme readme-384 (-> (select :*) (from :foo) (where [:< :expired_at (sql/raw ["now() - '" #sql/param :t " seconds'"])]) @@ -393,7 +398,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-396 +(seancorfield.readme/defreadme readme-401 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -409,7 +414,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-412 +(seancorfield.readme/defreadme readme-417 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -421,7 +426,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-424 +(seancorfield.readme/defreadme readme-429 (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] @@ -435,7 +440,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-438 +(seancorfield.readme/defreadme readme-443 (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]) @@ -455,7 +460,7 @@ call-qualify-map (limit 50) (offset 10))) ) -(seancorfield.readme/defreadme readme-458 +(seancorfield.readme/defreadme readme-463 big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]] @@ -475,26 +480,24 @@ big-complicated-map :limit 50 :offset 10} ) -(seancorfield.readme/defreadme readme-478 +(seancorfield.readme/defreadme readme-483 (sql/format big-complicated-map {:param1 "gabba" :param2 2}) -=> [#sql/regularize - "SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 - FROM foo f, baz b - INNER JOIN draq ON f.b = draq.x - LEFT JOIN clod c ON f.a = c.d - RIGHT JOIN bock ON bock.z = c.e - WHERE ((f.a = ? AND b.baz <> ?) - OR (? < ? AND ? < ?) - OR (f.e in (?, ?, ?)) - OR f.e BETWEEN ? AND ?) - GROUP BY f.a, c.e - HAVING ? < f.e - ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST - LIMIT ? - OFFSET ? " - "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] +=> [" +SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 +FROM foo f, baz b +INNER JOIN draq ON f.b = draq.x +LEFT JOIN clod c ON f.a = c.d +RIGHT JOIN bock ON bock.z = c.e +WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) +GROUP BY f.a, c.e +HAVING ? < f.e +ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST +LIMIT ? +OFFSET ? +" +"bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ) -(seancorfield.readme/defreadme readme-497 +(seancorfield.readme/defreadme readme-500 ;; Printable and readable (= big-complicated-map (read-string (pr-str big-complicated-map))) => true @@ -506,7 +509,7 @@ big-complicated-map -(seancorfield.readme/defreadme readme-509 +(seancorfield.readme/defreadme readme-512 (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " (fmt/to-sql lower) " AND " (fmt/to-sql upper))) @@ -517,23 +520,23 @@ big-complicated-map -(seancorfield.readme/defreadme readme-520 +(seancorfield.readme/defreadme readme-523 ;; Takes a MapEntry of the operator & clause data, plus the entire SQL map (defmethod fmt/format-clause :foobar [[op v] sqlmap] (str "FOOBAR " (fmt/to-sql v))) ) -(seancorfield.readme/defreadme readme-525 +(seancorfield.readme/defreadme readme-528 (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] ) -(seancorfield.readme/defreadme readme-529 +(seancorfield.readme/defreadme readme-532 (require '[honeysql.helpers :refer [defhelper]]) ;; Defines a helper function, and allows 'build' to recognize your clause (defhelper foobar [m args] (assoc m :foobar (first args))) ) -(seancorfield.readme/defreadme readme-536 +(seancorfield.readme/defreadme readme-539 (-> (select :a :b) (foobar :baz) sql/format) => ["SELECT a, b FOOBAR baz"] @@ -541,7 +544,7 @@ big-complicated-map -(seancorfield.readme/defreadme readme-544 +(seancorfield.readme/defreadme readme-547 (fmt/register-clause! :foobar 110) ) From 867d5d3482fa87f18c1fe372b0cb7951e76ed472 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 19:24:17 -0700 Subject: [PATCH 037/254] Implement composite; clean up readme --- README.md | 27 +++++++------ src/honey/sql.cljc | 7 ++-- src/honey/sql/helpers.cljc | 1 + src/readme.clj | 77 +++++++++++++++++++------------------- 4 files changed, 56 insertions(+), 56 deletions(-) diff --git a/README.md b/README.md index 5c7c44a..6f9d441 100644 --- a/README.md +++ b/README.md @@ -222,13 +222,12 @@ VALUES (?, (?, ?)), (?, (?, ?)) ### Updates -Updates are possible too (note the double S in `sset` to avoid clashing -with `clojure.core/set`): +Updates are possible too: ```clojure (-> (helpers/update :films) - (sset {:kind "dramatic" - :watched (sql/call :+ :watched 1)}) + (set {:kind "dramatic" + :watched [:+ :watched 1]}) (where [:= :kind "drama"]) (sql/format {:pretty? true})) => [" @@ -329,16 +328,16 @@ to identify inline parameter values, and how to add in raw SQL fragments! (def call-qualify-map (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) - (where [:= :a (???/param :baz)] [:= :b [:inline 42]]))) + (where [:= :a [:param :baz]] [:= :b [:inline 42]]))) ``` ```clojure call-qualify-map -=> '{:where [:and [:= :a ???/param :baz] [:= :b [:inline 42]]] +=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ``` ```clojure -(sql/format call-qualify-map :??? {:baz "BAZ"}) +(sql/format call-qualify-map {:params {:baz "BAZ"}}) => ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ``` @@ -370,13 +369,13 @@ will not be lifted out as parameters, so they end up in the SQL string as-is. Raw SQL can also be supplied as a vector of strings and values. Strings are rendered as-is into the formatted SQL string. Non-strings are lifted as -parameters. If you need a string parameter lifted, you must use `#sql/param` +parameters. If you need a string parameter lifted, you must use `:param` or the `param` helper. ```clojure (-> (select :*) (from :foo) - (where [:< :expired_at (sql/raw ["now() - '" 5 " seconds'"])]) + (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) (sql/format {:foo 5})) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ``` @@ -384,7 +383,7 @@ or the `param` helper. ```clojure (-> (select :*) (from :foo) - (where [:< :expired_at (sql/raw ["now() - '" #sql/param :t " seconds'"])]) + (where [:< :expired_at [:raw ["now() - '" [:param :t] " seconds'"]]]) (sql/format {:t 5})) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ``` @@ -450,9 +449,9 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify (left-join [:clod :c] [:= :f.a :c.d]) (right-join :bock [:= :bock.z :c.e]) (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] [:< 1 2 3] - [:in :f.e [1 (???/param :param2) 3]] + [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) (group :f.a :c.e) (having [:< 0 :f.e]) @@ -470,9 +469,9 @@ big-complicated-map :left-join [[:clod :c] [:= :f.a :c.d]] :right-join [:bock [:= :bock.z :c.e]] :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] [:< 1 2 3] - [:in :f.e [1 (????/param :param2) 3]] + [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]] :group-by [:f.a :c.e] :having [:< 0 :f.e] diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f53c700..138899c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -17,7 +17,7 @@ "The (default) order for known clauses. Can have items added and removed." [:with :with-recursive :intersect :union :union-all :except :except-all :select :insert-into :update :delete :delete-from :truncate - :columns :set :from + :columns :composite :set :from :join :left-join :right-join :inner-join :outer-join :full-join :cross-join :where :group-by :having :order-by :limit :offset :values @@ -169,8 +169,8 @@ [[] []] (map #(format-expr % opts) xs))) -(defn- format-columns [_ xs] - (let [[sqls params] (format-expr-list xs {:drop-ns? true})] +(defn- format-columns [k xs] + (let [[sqls params] (format-expr-list xs {:drop-ns? (= :columns k)})] (into [(str "(" (str/join ", " sqls) ")")] params))) (defn- format-selects [k xs] @@ -340,6 +340,7 @@ :delete-from #'format-selector :truncate #'format-selector :columns #'format-columns + :composite #'format-columns :set #'format-set-exprs :from #'format-selects :join #'format-join diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index e147cc2..dd2ed59 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -40,6 +40,7 @@ (defn delete-from [& args] (generic :delete-from args)) (defn truncate [& args] (generic :truncate args)) (defn columns [& args] (generic :columns args)) +(defn composite [& args] (generic :composite args)) (defn set [& args] (generic :set args)) (defn from [& args] (generic :from args)) (defn join [& args] (generic :join args)) diff --git a/src/readme.clj b/src/readme.clj index b996a51..f9f7e46 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -224,11 +224,10 @@ VALUES (?, (?, ?)), (?, (?, ?)) - -(seancorfield.readme/defreadme readme-228 +(seancorfield.readme/defreadme readme-227 (-> (helpers/update :films) - (sset {:kind "dramatic" - :watched (sql/call :+ :watched 1)}) + (set {:kind "dramatic" + :watched [:+ :watched 1]}) (where [:= :kind "drama"]) (sql/format {:pretty? true})) => [" @@ -251,7 +250,7 @@ WHERE kind = ? -(seancorfield.readme/defreadme readme-254 +(seancorfield.readme/defreadme readme-253 (-> (delete-from :films) (where [:<> :kind "musical"]) (sql/format)) @@ -260,7 +259,7 @@ WHERE kind = ? -(seancorfield.readme/defreadme readme-263 +(seancorfield.readme/defreadme readme-262 (-> (delete [:films :directors]) (from :films) (join :directors [:= :films.director_id :directors.id]) @@ -277,7 +276,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-280 +(seancorfield.readme/defreadme readme-279 (-> (truncate :films) (sql/format)) => ["TRUNCATE films"] @@ -287,7 +286,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-290 +(seancorfield.readme/defreadme readme-289 (sql/format {:union [(-> (select :*) (from :foo)) (-> (select :*) (from :bar))]}) => ["SELECT * FROM foo UNION SELECT * FROM bar"] @@ -297,11 +296,11 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-300 +(seancorfield.readme/defreadme readme-299 (-> (select :%count.*) (from :foo) sql/format) => ["SELECT count(*) FROM foo"] ) -(seancorfield.readme/defreadme readme-304 +(seancorfield.readme/defreadme readme-303 (-> (select :%max.id) (from :foo) sql/format) => ["SELECT max(id) FROM foo"] ) @@ -312,7 +311,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-315 +(seancorfield.readme/defreadme readme-314 (-> (select :id) (from :foo) (where [:= :a :?baz]) @@ -325,20 +324,20 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-328 +(seancorfield.readme/defreadme readme-327 (def call-qualify-map (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) - (where [:= :a (???/param :baz)] [:= :b [:inline 42]]))) + (where [:= :a [:param :baz]] [:= :b [:inline 42]]))) ) -(seancorfield.readme/defreadme readme-334 +(seancorfield.readme/defreadme readme-333 call-qualify-map -=> '{:where [:and [:= :a ???/param :baz] [:= :b [:inline 42]]] +=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ) -(seancorfield.readme/defreadme readme-340 -(sql/format call-qualify-map :??? {:baz "BAZ"}) +(seancorfield.readme/defreadme readme-339 +(sql/format call-qualify-map {:params {:baz "BAZ"}}) => ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ) @@ -347,7 +346,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-350 +(seancorfield.readme/defreadme readme-349 (-> (insert-into :sample) (values [{:location [:ST_SetSRID [:ST_MakePoint 0.291 32.621] @@ -373,18 +372,18 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-376 +(seancorfield.readme/defreadme readme-375 (-> (select :*) (from :foo) - (where [:< :expired_at (sql/raw ["now() - '" 5 " seconds'"])]) + (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) (sql/format {:foo 5})) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ) -(seancorfield.readme/defreadme readme-384 +(seancorfield.readme/defreadme readme-383 (-> (select :*) (from :foo) - (where [:< :expired_at (sql/raw ["now() - '" #sql/param :t " seconds'"])]) + (where [:< :expired_at [:raw ["now() - '" [:param :t] " seconds'"]]]) (sql/format {:t 5})) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ) @@ -398,7 +397,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-401 +(seancorfield.readme/defreadme readme-400 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -414,7 +413,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-417 +(seancorfield.readme/defreadme readme-416 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -426,7 +425,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-429 +(seancorfield.readme/defreadme readme-428 (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] @@ -440,7 +439,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-443 +(seancorfield.readme/defreadme readme-442 (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]) @@ -450,9 +449,9 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) (left-join [:clod :c] [:= :f.a :c.d]) (right-join :bock [:= :bock.z :c.e]) (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] [:< 1 2 3] - [:in :f.e [1 (???/param :param2) 3]] + [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) (group :f.a :c.e) (having [:< 0 :f.e]) @@ -460,7 +459,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) (limit 50) (offset 10))) ) -(seancorfield.readme/defreadme readme-463 +(seancorfield.readme/defreadme readme-462 big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]] @@ -470,9 +469,9 @@ big-complicated-map :left-join [[:clod :c] [:= :f.a :c.d]] :right-join [:bock [:= :bock.z :c.e]] :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz (???/param :param1)]] + [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] [:< 1 2 3] - [:in :f.e [1 (????/param :param2) 3]] + [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]] :group-by [:f.a :c.e] :having [:< 0 :f.e] @@ -480,7 +479,7 @@ big-complicated-map :limit 50 :offset 10} ) -(seancorfield.readme/defreadme readme-483 +(seancorfield.readme/defreadme readme-482 (sql/format big-complicated-map {:param1 "gabba" :param2 2}) => [" SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 @@ -497,7 +496,7 @@ OFFSET ? " "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ) -(seancorfield.readme/defreadme readme-500 +(seancorfield.readme/defreadme readme-499 ;; Printable and readable (= big-complicated-map (read-string (pr-str big-complicated-map))) => true @@ -509,7 +508,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-512 +(seancorfield.readme/defreadme readme-511 (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " (fmt/to-sql lower) " AND " (fmt/to-sql upper))) @@ -520,23 +519,23 @@ OFFSET ? -(seancorfield.readme/defreadme readme-523 +(seancorfield.readme/defreadme readme-522 ;; Takes a MapEntry of the operator & clause data, plus the entire SQL map (defmethod fmt/format-clause :foobar [[op v] sqlmap] (str "FOOBAR " (fmt/to-sql v))) ) -(seancorfield.readme/defreadme readme-528 +(seancorfield.readme/defreadme readme-527 (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] ) -(seancorfield.readme/defreadme readme-532 +(seancorfield.readme/defreadme readme-531 (require '[honeysql.helpers :refer [defhelper]]) ;; Defines a helper function, and allows 'build' to recognize your clause (defhelper foobar [m args] (assoc m :foobar (first args))) ) -(seancorfield.readme/defreadme readme-539 +(seancorfield.readme/defreadme readme-538 (-> (select :a :b) (foobar :baz) sql/format) => ["SELECT a, b FOOBAR baz"] @@ -544,7 +543,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-547 +(seancorfield.readme/defreadme readme-546 (fmt/register-clause! :foobar 110) ) From 8b2f0ef2922938c2bac0e618e0811c5afb1d39db Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 28 Sep 2020 20:45:43 -0700 Subject: [PATCH 038/254] Add locking select support via for/lock --- README.md | 42 ++++++++--- src/honey/sql.cljc | 34 +++++++-- src/honey/sql/helpers.cljc | 3 +- src/readme.clj | 122 ++++++++++++++++++------------- test/honey/sql/helpers_test.cljc | 6 ++ test/honey/sql_test.cljc | 40 ++++++++++ 6 files changed, 177 insertions(+), 70 deletions(-) create mode 100644 test/honey/sql/helpers_test.cljc diff --git a/README.md b/README.md index 6f9d441..11e59e4 100644 --- a/README.md +++ b/README.md @@ -23,7 +23,9 @@ README readability; honeysql does not generate pretty-printed SQL. ## Usage ```clojure +(refer-clojure :exclude '[for group-by set update]) (require '[honey.sql :as sql] + ;; caution: this overwrites for, group-by, set, and update '[honey.sql.helpers :refer :all :as helpers]) ``` @@ -407,22 +409,38 @@ Valid `:dialect` options are `:ansi` (the default, use this for PostgreSQL), #### Locking -_This is not implemented yet._ +The ANSI/PostgreSQL/SQLServer dialects support locking selects via a `FOR` clause as follows: -To issue a locking select, add a `:lock` to the query or use the lock helper. The lock value must be a map with a `:mode` value. The built-in -modes are the standard `:update` (FOR UPDATE) or the vendor-specific `:mysql-share` (LOCK IN SHARE MODE) or `:postresql-share` (FOR SHARE). The -lock map may also provide a `:wait` value, which if false will append the NOWAIT parameter, supported by PostgreSQL. +* `:for [ ]` where `` is required and may be one of: + * `:update` + * `:no-key-update` + * `:share` + * `:key-share` +* Both `` and `` are optional but if present, `` must either be: + * a single table name (as a keyword) or + * a sequence of table names (as keywords) +* `` must be `:nowait` if it is present. + +If `` and `` are both omitted, you may also omit the `[`..`]` and just say `:for :update` etc. ```clojure (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) - (lock :mode :update) - (sql/format)) -=> ["SELECT foo.a FROM foo WHERE foo.a = ? FOR UPDATE" "baz"] + (for :update) + (format)) +=> ["SELECT foo.a FROM foo WHERE (foo.a = ?) FOR UPDATE" "baz"] ``` -To support novel lock modes, implement the `format-lock-clause` multimethod. +If the `:mysql` dialect is selected, an additional locking clause is available: +`:lock :in-share-mode`. +```clojure +(sql/format {:select [:*] :from :foo + :where [:= :name [:inline "Jones"]] + :lock [:in-share-mode]} + {:dialect :mysql :quoted false}) +=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] +``` To be able to use dashes in quoted names, you can pass ```:allow-dashed-names true``` as an argument to the ```format``` function. ```clojure @@ -430,8 +448,8 @@ To be able to use dashes in quoted names, you can pass ```:allow-dashed-names tr {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] :where [:= :f.foo-id 12345]} - :allow-dashed-names? true - :quoting :ansi) + {:allow-dashed-names? true ; not implemented yet + :quoted true}) => ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] ``` @@ -443,7 +461,7 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]) - (modifiers :distinct) ; this is not implemented yet + #_(modifiers :distinct) ; this is not implemented yet (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) @@ -453,7 +471,7 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify [:< 1 2 3] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) - (group :f.a :c.e) + (group-by :f.a :c.e) (having [:< 0 :f.e]) (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) (limit 50) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 138899c..c1b3ece 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -13,6 +13,7 @@ ;; dynamic dialect handling for formatting +(declare clause-format) (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." [:with :with-recursive :intersect :union :union-all :except :except-all @@ -20,7 +21,7 @@ :columns :composite :set :from :join :left-join :right-join :inner-join :outer-join :full-join :cross-join - :where :group-by :having :order-by :limit :offset :values + :where :group-by :having :order-by :limit :offset :for :values :on-conflict :on-constraint :do-nothing :do-update-set :returning]) @@ -44,10 +45,15 @@ {:ansi {:quote #(str \" % \")} :sqlserver {:quote #(str \[ % \])} :mysql {:quote #(str \` % \`) - :clause-order-fn #(add-clause-before - (filterv (complement #{:set}) %) - :set - :where)} + :clause-order-fn (fn [order] + ;; :lock is like :for + (swap! clause-format assoc :lock + (get @clause-format :for)) + ;; MySQL :set has different priority + ;; and :lock is between :for and :values + (-> (filterv (complement #{:set}) order) + (add-clause-before :set :where) + (add-clause-before :lock :values)))} :oracle {:quote #(str \" % \") :as false}}) ; should become defonce @@ -256,6 +262,21 @@ sqls dirs)))] params))) +(defn- format-lock-strength [k xs] + (let [[strength tables nowait] (if (sequential? xs) xs [xs])] + [(str (sql-kw k) " " (sql-kw strength) + (when tables + (str + (cond (= :nowait tables) + (str " NOWAIT") + (sequential? tables) + (str " OF " + (str/join ", " (map #'format-entity tables))) + :else + (str " OF " (format-entity tables))) + (when nowait + (str " NOWAIT")))))])) + (defn- format-values [k xs] (cond (sequential? (first xs)) ;; [[1 2 3] [4 5 6]] @@ -356,6 +377,7 @@ :order-by #'format-order-by :limit #'format-on-expr :offset #'format-on-expr + :for #'format-lock-strength :values #'format-values :on-conflict #'format-on-conflict :on-constraint #'format-selector @@ -381,7 +403,7 @@ ;:delete-from 80 ;:truncate 85 ;:columns 90 - :composite 95 + ;:composite 95 ;; no longer needed/supported :set0 100 ; low-priority set clause ;:from 110 ;:join 120 diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index dd2ed59..c78ed1a 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -2,7 +2,7 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." - (:refer-clojure :exclude [update set group-by]) + (:refer-clojure :exclude [update set group-by for]) (:require [honey.sql :as h])) (defn- default-merge [current args] @@ -56,6 +56,7 @@ (defn order-by [& args] (generic :order-by args)) (defn limit [& args] (generic :limit args)) (defn offset [& args] (generic :offset args)) +(defn for [& args] (generic :for args)) (defn values [& args] (generic :values args)) (defn on-conflict [& args] (generic :on-conflict args)) (defn on-constraint [& args] (generic :on-constraint args)) diff --git a/src/readme.clj b/src/readme.clj index f9f7e46..0da2a2d 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -23,13 +23,15 @@ (seancorfield.readme/defreadme readme-25 +(refer-clojure :exclude '[for group-by set update]) (require '[honey.sql :as sql] + ;; caution: this overwrites for, group-by, set, and update '[honey.sql.helpers :refer :all :as helpers]) ) -(seancorfield.readme/defreadme readme-32 +(seancorfield.readme/defreadme readme-34 (def sqlmap {:select [:a :b :c] :from [:foo] :where [:= :f.a "baz"]}) @@ -41,7 +43,7 @@ -(seancorfield.readme/defreadme readme-44 +(seancorfield.readme/defreadme readme-46 (sql/format sqlmap) => ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] ) @@ -62,7 +64,7 @@ -(seancorfield.readme/defreadme readme-65 +(seancorfield.readme/defreadme readme-67 (def q-sqlmap {:select [:foo/a :foo/b :foo/c] :from [:foo] :where [:= :foo/a "baz"]}) @@ -76,7 +78,7 @@ -(seancorfield.readme/defreadme readme-79 +(seancorfield.readme/defreadme readme-81 (-> (select :a :b :c) (from :foo) (where [:= :f.a "baz"])) @@ -84,7 +86,7 @@ -(seancorfield.readme/defreadme readme-87 +(seancorfield.readme/defreadme readme-89 (= (-> (select :*) (from :foo)) (-> (from :foo) (select :*))) => true @@ -92,14 +94,14 @@ -(seancorfield.readme/defreadme readme-95 +(seancorfield.readme/defreadme readme-97 (-> sqlmap (select :d)) => '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} ) -(seancorfield.readme/defreadme readme-102 +(seancorfield.readme/defreadme readme-104 (-> sqlmap (dissoc :select) (select :*) @@ -110,7 +112,7 @@ -(seancorfield.readme/defreadme readme-113 +(seancorfield.readme/defreadme readme-115 (-> (select :*) (from :foo) (where [:= :a 1] [:< :b 100]) @@ -121,7 +123,7 @@ -(seancorfield.readme/defreadme readme-124 +(seancorfield.readme/defreadme readme-126 (-> (select :a [:b :bar] :c [:d :x]) (from [:foo :quux]) (where [:= :quux.a 1] [:< :bar 100]) @@ -138,7 +140,7 @@ -(seancorfield.readme/defreadme readme-141 +(seancorfield.readme/defreadme readme-143 (-> (insert-into :properties) (columns :name :surname :age) (values @@ -157,7 +159,7 @@ VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) -(seancorfield.readme/defreadme readme-160 +(seancorfield.readme/defreadme readme-162 (-> (insert-into :properties) (values [{:name "John" :surname "Smith" :age 34} {:name "Andrew" :surname "Cooper" :age 12} @@ -176,7 +178,7 @@ VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) -(seancorfield.readme/defreadme readme-179 +(seancorfield.readme/defreadme readme-181 (let [user-id 12345 role-name "user"] (-> (insert-into :user_profile_to_role) @@ -194,7 +196,7 @@ VALUES (?, (SELECT id FROM role WHERE name = ?)) "user"] ) -(seancorfield.readme/defreadme readme-197 +(seancorfield.readme/defreadme readme-199 (-> (select :*) (from :foo) (where [:in :foo.a (-> (select :a) (from :bar))]) @@ -206,7 +208,7 @@ VALUES (?, (SELECT id FROM role WHERE name = ?)) -(seancorfield.readme/defreadme readme-209 +(seancorfield.readme/defreadme readme-211 (-> (insert-into :comp_table) (columns :name :comp_column) (values @@ -224,7 +226,7 @@ VALUES (?, (?, ?)), (?, (?, ?)) -(seancorfield.readme/defreadme readme-227 +(seancorfield.readme/defreadme readme-229 (-> (helpers/update :films) (set {:kind "dramatic" :watched [:+ :watched 1]}) @@ -250,7 +252,7 @@ WHERE kind = ? -(seancorfield.readme/defreadme readme-253 +(seancorfield.readme/defreadme readme-255 (-> (delete-from :films) (where [:<> :kind "musical"]) (sql/format)) @@ -259,7 +261,7 @@ WHERE kind = ? -(seancorfield.readme/defreadme readme-262 +(seancorfield.readme/defreadme readme-264 (-> (delete [:films :directors]) (from :films) (join :directors [:= :films.director_id :directors.id]) @@ -276,7 +278,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-279 +(seancorfield.readme/defreadme readme-281 (-> (truncate :films) (sql/format)) => ["TRUNCATE films"] @@ -286,7 +288,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-289 +(seancorfield.readme/defreadme readme-291 (sql/format {:union [(-> (select :*) (from :foo)) (-> (select :*) (from :bar))]}) => ["SELECT * FROM foo UNION SELECT * FROM bar"] @@ -296,11 +298,11 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-299 +(seancorfield.readme/defreadme readme-301 (-> (select :%count.*) (from :foo) sql/format) => ["SELECT count(*) FROM foo"] ) -(seancorfield.readme/defreadme readme-303 +(seancorfield.readme/defreadme readme-305 (-> (select :%max.id) (from :foo) sql/format) => ["SELECT max(id) FROM foo"] ) @@ -311,7 +313,7 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-314 +(seancorfield.readme/defreadme readme-316 (-> (select :id) (from :foo) (where [:= :a :?baz]) @@ -324,19 +326,19 @@ WHERE kind <> ? -(seancorfield.readme/defreadme readme-327 +(seancorfield.readme/defreadme readme-329 (def call-qualify-map (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) (from :foo) (where [:= :a [:param :baz]] [:= :b [:inline 42]]))) ) -(seancorfield.readme/defreadme readme-333 +(seancorfield.readme/defreadme readme-335 call-qualify-map => '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ) -(seancorfield.readme/defreadme readme-339 +(seancorfield.readme/defreadme readme-341 (sql/format call-qualify-map {:params {:baz "BAZ"}}) => ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ) @@ -346,7 +348,7 @@ call-qualify-map -(seancorfield.readme/defreadme readme-349 +(seancorfield.readme/defreadme readme-351 (-> (insert-into :sample) (values [{:location [:ST_SetSRID [:ST_MakePoint 0.291 32.621] @@ -372,7 +374,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-375 +(seancorfield.readme/defreadme readme-377 (-> (select :*) (from :foo) (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) @@ -380,7 +382,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ) -(seancorfield.readme/defreadme readme-383 +(seancorfield.readme/defreadme readme-385 (-> (select :*) (from :foo) (where [:< :expired_at [:raw ["now() - '" [:param :t] " seconds'"]]]) @@ -397,7 +399,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-400 +(seancorfield.readme/defreadme readme-402 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -413,25 +415,43 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-416 -(-> (select :foo.a) - (from :foo) - (where [:= :foo.a "baz"]) - (lock :mode :update) - (sql/format)) -=> ["SELECT foo.a FROM foo WHERE foo.a = ? FOR UPDATE" "baz"] -) + + + + + + (seancorfield.readme/defreadme readme-428 +(sql/format {:select [:*] :from :foo + :where [:= :name [:inline "Jones"]] + :lock [:in-share-mode]} + {:dialect :mysql :quoted false}) +=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] +) + +(seancorfield.readme/defreadme readme-436 +(-> (select :foo.a) + (from :foo) + (where [:= :foo.a "baz"]) + (for :update) + (format)) +=> ["SELECT foo.a FROM foo WHERE (foo.a = ?) FOR UPDATE" "baz"] +) + + + + +(seancorfield.readme/defreadme readme-448 (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] :where [:= :f.foo-id 12345]} - :allow-dashed-names? true - :quoting :ansi) + {:allow-dashed-names? true ; not implemented yet + :quoted true}) => ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] ) @@ -439,11 +459,11 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-442 +(seancorfield.readme/defreadme readme-462 (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]) - (modifiers :distinct) ; this is not implemented yet + #_(modifiers :distinct) ; this is not implemented yet (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) @@ -453,13 +473,13 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) [:< 1 2 3] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) - (group :f.a :c.e) + (group-by :f.a :c.e) (having [:< 0 :f.e]) (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) (limit 50) (offset 10))) ) -(seancorfield.readme/defreadme readme-462 +(seancorfield.readme/defreadme readme-482 big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]] @@ -479,7 +499,7 @@ big-complicated-map :limit 50 :offset 10} ) -(seancorfield.readme/defreadme readme-482 +(seancorfield.readme/defreadme readme-502 (sql/format big-complicated-map {:param1 "gabba" :param2 2}) => [" SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 @@ -496,7 +516,7 @@ OFFSET ? " "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ) -(seancorfield.readme/defreadme readme-499 +(seancorfield.readme/defreadme readme-519 ;; Printable and readable (= big-complicated-map (read-string (pr-str big-complicated-map))) => true @@ -508,7 +528,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-511 +(seancorfield.readme/defreadme readme-531 (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " (fmt/to-sql lower) " AND " (fmt/to-sql upper))) @@ -519,23 +539,23 @@ OFFSET ? -(seancorfield.readme/defreadme readme-522 +(seancorfield.readme/defreadme readme-542 ;; Takes a MapEntry of the operator & clause data, plus the entire SQL map (defmethod fmt/format-clause :foobar [[op v] sqlmap] (str "FOOBAR " (fmt/to-sql v))) ) -(seancorfield.readme/defreadme readme-527 +(seancorfield.readme/defreadme readme-547 (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] ) -(seancorfield.readme/defreadme readme-531 +(seancorfield.readme/defreadme readme-551 (require '[honeysql.helpers :refer [defhelper]]) ;; Defines a helper function, and allows 'build' to recognize your clause (defhelper foobar [m args] (assoc m :foobar (first args))) ) -(seancorfield.readme/defreadme readme-538 +(seancorfield.readme/defreadme readme-558 (-> (select :a :b) (foobar :baz) sql/format) => ["SELECT a, b FOOBAR baz"] @@ -543,7 +563,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-546 +(seancorfield.readme/defreadme readme-566 (fmt/register-clause! :foobar 110) ) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc new file mode 100644 index 0000000..2c37b4a --- /dev/null +++ b/test/honey/sql/helpers_test.cljc @@ -0,0 +1,6 @@ +;; copyright (c) sean corfield, all rights reserved + +(ns honey.sql.helpers-test + (:require #?(:clj [clojure.test :refer [deftest is testing]] + :cljs [cljs.test :refer-macros [deftest is testing]]) + [honey.sql.helpers :as sut])) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 8071fb1..915e4a4 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -402,6 +402,46 @@ :from [[:foo :f]] :cross-join [[:bar :b]]})))) +(deftest locking-select-tests + (testing "PostgreSQL/ANSI FOR" + (is (= ["SELECT * FROM foo FOR UPDATE"] + (format {:select [:*] :from :foo :for :update}))) + (is (= ["SELECT * FROM foo FOR NO KEY UPDATE"] + (format {:select [:*] :from :foo :for :no-key-update}))) + (is (= ["SELECT * FROM foo FOR SHARE"] + (format {:select [:*] :from :foo :for :share}))) + (is (= ["SELECT * FROM foo FOR KEY SHARE"] + (format {:select [:*] :from :foo :for :key-share}))) + (is (= ["SELECT * FROM foo FOR UPDATE"] + (format {:select [:*] :from :foo :for [:update]}))) + (is (= ["SELECT * FROM foo FOR NO KEY UPDATE"] + (format {:select [:*] :from :foo :for [:no-key-update]}))) + (is (= ["SELECT * FROM foo FOR SHARE"] + (format {:select [:*] :from :foo :for [:share]}))) + (is (= ["SELECT * FROM foo FOR KEY SHARE"] + (format {:select [:*] :from :foo :for [:key-share]}))) + (is (= ["SELECT * FROM foo FOR UPDATE NOWAIT"] + (format {:select [:*] :from :foo :for [:update :nowait]}))) + (is (= ["SELECT * FROM foo FOR UPDATE OF bar NOWAIT"] + (format {:select [:*] :from :foo :for [:update :bar :nowait]}))) + (is (= ["SELECT * FROM foo FOR UPDATE OF bar, quux"] + (format {:select [:*] :from :foo :for [:update [:bar :quux]]})))) + (testing "MySQL for/lock" + ;; these examples come from: + (is (= ["SELECT * FROM t1 WHERE c1 = (SELECT c1 FROM t2) FOR UPDATE"] ; portable + (format {:select [:*] :from :t1 + :where [:= :c1 {:select [:c1] :from :t2}] + :for [:update]}))) + (is (= ["SELECT * FROM t1 WHERE c1 = (SELECT c1 FROM t2 FOR UPDATE) FOR UPDATE"] + (format {:select [:*] :from :t1 + :where [:= :c1 {:select [:c1] :from :t2 :for [:update]}] + :for [:update]}))) + (is (= ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] ; MySQL-specific + (format {:select [:*] :from :foo + :where [:= :name [:inline "Jones"]] + :lock [:in-share-mode]} + {:dialect :mysql :quoted false}))))) + (deftest insert-example-tests ;; these examples are taken from https://www.postgresql.org/docs/13/sql-insert.html (is (= [" From b94f169af3df498c3f07f5849d4ecca2199204aa Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 29 Sep 2020 14:20:34 -0700 Subject: [PATCH 039/254] Normalize symbol/keyword logic We will allow symbols anywhere that we previously allowed keywords. --- src/honey/sql.cljc | 7 +++++-- src/readme.clj | 42 ++++++++++++++++++++---------------------- 2 files changed, 25 insertions(+), 24 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index c1b3ece..22ee1ea 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -321,13 +321,13 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-on-conflict [k x] - (if (keyword? x) + (if (or (keyword? x) (symbol? x)) [(str (sql-kw k) " (" (format-entity x) ")")] (let [[sql & params] (format-dsl x)] (into [(str (sql-kw k) " " sql)] params)))) (defn- format-do-update-set [k x] - (if (keyword? x) + (if (or (keyword? x) (symbol? x)) (let [e (format-entity x {:drop-ns? true})] [(str (sql-kw k) " " e " = EXCLUDED." e)]) (format-set-exprs k x))) @@ -523,6 +523,9 @@ (sequential? x) (let [op (first x) + ;; normalize symbols to keywords here -- makes the subsequent + ;; logic easier since we use op to lookup things in hash maps: + op (if (symbol? op) (keyword (name op)) op) op-ignore-nil #{:and :or} op-variadic #{:and :or :+ :* :||}] (if (keyword? op) diff --git a/src/readme.clj b/src/readme.clj index 0da2a2d..bc8136f 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -423,17 +423,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) - - -(seancorfield.readme/defreadme readme-428 -(sql/format {:select [:*] :from :foo - :where [:= :name [:inline "Jones"]] - :lock [:in-share-mode]} - {:dialect :mysql :quoted false}) -=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] -) - -(seancorfield.readme/defreadme readme-436 +(seancorfield.readme/defreadme readme-426 (-> (select :foo.a) (from :foo) (where [:= :foo.a "baz"]) @@ -444,8 +434,16 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) +(seancorfield.readme/defreadme readme-437 +(sql/format {:select [:*] :from :foo + :where [:= :name [:inline "Jones"]] + :lock [:in-share-mode]} + {:dialect :mysql :quoted false}) +=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] +) -(seancorfield.readme/defreadme readme-448 + +(seancorfield.readme/defreadme readme-446 (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] @@ -459,7 +457,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -(seancorfield.readme/defreadme readme-462 +(seancorfield.readme/defreadme readme-460 (def big-complicated-map (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]) @@ -479,7 +477,7 @@ VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) (limit 50) (offset 10))) ) -(seancorfield.readme/defreadme readme-482 +(seancorfield.readme/defreadme readme-480 big-complicated-map => {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] [[:now]] [[:raw "@x := 10"]]] @@ -499,7 +497,7 @@ big-complicated-map :limit 50 :offset 10} ) -(seancorfield.readme/defreadme readme-502 +(seancorfield.readme/defreadme readme-500 (sql/format big-complicated-map {:param1 "gabba" :param2 2}) => [" SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 @@ -516,7 +514,7 @@ OFFSET ? " "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] ) -(seancorfield.readme/defreadme readme-519 +(seancorfield.readme/defreadme readme-517 ;; Printable and readable (= big-complicated-map (read-string (pr-str big-complicated-map))) => true @@ -528,7 +526,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-531 +(seancorfield.readme/defreadme readme-529 (defmethod fmt/fn-handler "betwixt" [_ field lower upper] (str (fmt/to-sql field) " BETWIXT " (fmt/to-sql lower) " AND " (fmt/to-sql upper))) @@ -539,23 +537,23 @@ OFFSET ? -(seancorfield.readme/defreadme readme-542 +(seancorfield.readme/defreadme readme-540 ;; Takes a MapEntry of the operator & clause data, plus the entire SQL map (defmethod fmt/format-clause :foobar [[op v] sqlmap] (str "FOOBAR " (fmt/to-sql v))) ) -(seancorfield.readme/defreadme readme-547 +(seancorfield.readme/defreadme readme-545 (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] ) -(seancorfield.readme/defreadme readme-551 +(seancorfield.readme/defreadme readme-549 (require '[honeysql.helpers :refer [defhelper]]) ;; Defines a helper function, and allows 'build' to recognize your clause (defhelper foobar [m args] (assoc m :foobar (first args))) ) -(seancorfield.readme/defreadme readme-558 +(seancorfield.readme/defreadme readme-556 (-> (select :a :b) (foobar :baz) sql/format) => ["SELECT a, b FOOBAR baz"] @@ -563,7 +561,7 @@ OFFSET ? -(seancorfield.readme/defreadme readme-566 +(seancorfield.readme/defreadme readme-564 (fmt/register-clause! :foobar 110) ) From a789d4a4ffcd46ef9e83a3f46987edb641d20551 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 29 Sep 2020 14:40:03 -0700 Subject: [PATCH 040/254] Support registration of new infix operators and new function/syntax --- src/honey/sql.cljc | 117 +++++++++++++++++++++++++++++---------------- 1 file changed, 75 insertions(+), 42 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 22ee1ea..e9c4e1e 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -471,7 +471,11 @@ (into (map str "+-*/%|&^=<>")) (into (keys infix-aliases)) (into (vals infix-aliases)) - (->> (into #{} (map keyword))))) + (->> (into #{} (map keyword))) + (atom))) + +(def ^:private op-ignore-nil (atom #{:and :or})) +(def ^:private op-variadic (atom #{:and :or :+ :* :||})) (defn- sqlize-value [x] (cond @@ -482,37 +486,38 @@ :else (str x))) (def ^:private special-syntax - {:array - (fn [k [arr]] - (let [[sqls params] (format-expr-list arr)] - (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) - :between - (fn [k [x a b]] - (let [[sql-x & params-x] (format-expr x {:nested? true}) - [sql-a & params-a] (format-expr a {:nested? true}) - [sql-b & params-b] (format-expr b {:nested? true})] - (-> [(str sql-x " BETWEEN " sql-a " AND " sql-b)] - (into params-x) - (into params-a) - (into params-b)))) - :cast - (fn [k [x type]] - (let [[sql & params] (format-expr x)] - (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) - :default - (fn [k []] - ["DEFAULT"]) - :inline - (fn [k [x]] - [(sqlize-value x)]) - :interval - (fn [k [n units]] - (let [[sql & params] (format-expr n)] - (into [(str "INTERVAL " sql " " (sql-kw units))] params))) - :not - (fn [k [x]] - (let [[sql & params] (format-expr x)] - (into [(str "NOT " sql)] params)))}) + (atom + {:array + (fn [_ [arr]] + (let [[sqls params] (format-expr-list arr)] + (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) + :between + (fn [_ [x a b]] + (let [[sql-x & params-x] (format-expr x {:nested? true}) + [sql-a & params-a] (format-expr a {:nested? true}) + [sql-b & params-b] (format-expr b {:nested? true})] + (-> [(str sql-x " BETWEEN " sql-a " AND " sql-b)] + (into params-x) + (into params-a) + (into params-b)))) + :cast + (fn [_ [x type]] + (let [[sql & params] (format-expr x)] + (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) + :default + (fn [_ []] + ["DEFAULT"]) + :inline + (fn [_ [x]] + [(sqlize-value x)]) + :interval + (fn [_ [n units]] + (let [[sql & params] (format-expr n)] + (into [(str "INTERVAL " sql " " (sql-kw units))] params))) + :not + (fn [_ [x]] + (let [[sql & params] (format-expr x)] + (into [(str "NOT " sql)] params)))})) (defn format-expr [x & [{:keys [nested?] :as opts}]] (cond (or (keyword? x) (symbol? x)) @@ -525,13 +530,11 @@ (let [op (first x) ;; normalize symbols to keywords here -- makes the subsequent ;; logic easier since we use op to lookup things in hash maps: - op (if (symbol? op) (keyword (name op)) op) - op-ignore-nil #{:and :or} - op-variadic #{:and :or :+ :* :||}] + op (if (symbol? op) (keyword (name op)) op)] (if (keyword? op) - (cond (infix-ops op) - (if (op-variadic op) ; no aliases here, no special semantics - (let [x (if (op-ignore-nil op) (remove nil? x) x) + (cond (contains? @infix-ops op) + (if (contains? @op-variadic op) ; no aliases here, no special semantics + (let [x (if (contains? @op-ignore-nil op) (remove nil? x) x) [sqls params] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') @@ -566,8 +569,8 @@ (vector) (into p1) (into p2))))) - (special-syntax op) - (let [formatter (special-syntax op)] + (contains? @special-syntax op) + (let [formatter (get @special-syntax op)] (formatter op (rest x))) :else (let [args (rest x) @@ -641,12 +644,13 @@ New clauses are registered in the base order and the current order so that any dialect selections are able to include them while still working - predictably from the base order. Caveat: that means if you are a new + predictably from the base order. Caveat: that means if you register a new clause `before` a clause that is ordered differently in different dialects, your new clause may also end up in a different place. The only clause so far where that would matter is `:set` which differs in - MySQL..." + MySQL." [clause formatter before] + (assert (keyword? clause)) (let [f (if (keyword? formatter) (get @clause-format formatter) formatter)] @@ -657,6 +661,35 @@ (swap! current-clause-order add-clause-before clause before) (swap! clause-format assoc clause f))) +(defn register-fn! + "Register a new function (as special syntax). The `formatter` is either + a keyword, meaning that this new function should use the same syntax as + an existing function, or a function of two arguments that generates a + SQL string and parameters (as a vector). The two arguments are the name + of the function (as a keyword) and a sequence of the arguments from the + DSL." + [function formatter] + (assert (keyword? function)) + (let [f (if (keyword? formatter) + (get @special-syntax formatter) + formatter)] + (when-not (and f (fn? f)) + (throw (ex-info "The formatter must be a function or existing fn name" + {:type (type formatter)}))) + (swap! special-syntax assoc function f))) + +(defn register-op! + "Register a new infix operator. Operators can be defined to be variadic (the + default is that they are binary) and may choose to ignore `nil` arguments + (this can make it easier to programmatically construct the DSL)." + [op & {:keys [variadic? ignore-nil?]}] + (assert (keyword? op)) + (swap! infix-ops conj op) + (when variadic? + (swap! op-variadic conj op)) + (when ignore-nil? + (swap! op-ignore-nil conj op))) + (comment (format {:truncate :foo}) (format-expr [:= :id 1]) From ddef4068bac180a2106072ac011452e14e9d63f9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 30 Sep 2020 13:00:09 -0700 Subject: [PATCH 041/254] Ensure DSL elements can be symbols (as well as keywords) --- src/honey/sql.cljc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index e9c4e1e..6340cc5 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -431,12 +431,12 @@ (defn- format-dsl [x & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] - (if-let [xs (k x)] + (if-let [xs (or (k x) (let [s (symbol (name k))] (get x s)))] (let [formatter (k @clause-format) [sql' & params'] (formatter k xs)] [(conj sql sql') (if params' (into params params') params) - (dissoc leftover k)]) + (dissoc leftover k (symbol (name k)))]) [sql params leftover])) [[] [] x] *clause-order*)] From 9f8d1a856411f4b84ff6c758f4e2dfc00befe642 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 1 Oct 2020 23:30:18 -0700 Subject: [PATCH 042/254] Implement :?foo [:param :foo] and primitive [:raw "sql"] --- README.md | 4 +-- src/honey/sql.cljc | 65 ++++++++++++++++++++++++++++++---------------- src/readme.clj | 4 +-- 3 files changed, 47 insertions(+), 26 deletions(-) diff --git a/README.md b/README.md index 11e59e4..3981f49 100644 --- a/README.md +++ b/README.md @@ -317,8 +317,8 @@ Keywords that begin with `?` are interpreted as bindable parameters: (-> (select :id) (from :foo) (where [:= :a :?baz]) - (sql/format :params {:baz "BAZ"})) -=> ["SELECT id FROM foo WHERE a = ?" "BAZ"] + (sql/format {:params {:baz "BAZ"}})) +=> ["SELECT id FROM foo WHERE (a = ?)" "BAZ"] ``` ### Miscellaneous diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 6340cc5..0c10921 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -85,28 +85,40 @@ (-> k (name) (upper-case) (str/replace "-" " "))) (defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] - (let [q (if *quoted* (:quote *dialect*) identity) - call (fn [f x] (str f "(" x ")")) - [f t c] (if-let [n (when-not (or drop-ns? (string? x)) - (namespace x))] - [nil n (name x)] - (let [[t c] (if aliased? - [(name x)] - (str/split (name x) #"\."))] - ;; I really dislike like %func.arg shorthand syntax! - (cond (= \% (first t)) - [(subs t 1) nil c] - c - [nil t c] - :else - [nil nil t])))] + (let [q (if *quoted* (:quote *dialect*) identity) + [t c] (if-let [n (when-not (or drop-ns? (string? x)) + (namespace x))] + [n (name x)] + (if aliased? + [nil (name x)] + (let [[t c] (str/split (name x) #"\.")] + (if c [t c] [nil t]))))] (cond->> c (not= "*" c) (q) t - (str (q t) ".") - f - (call f)))) + (str (q t) ".")))) + +(defn- ->param [k] + (with-meta (constantly k) + {::wrapper + (fn [fk {:keys [params]}] + (let [k (fk)] + (if (contains? params k) + (get params k) + (throw (ex-info (str "missing parameter value for " k) + {:params (keys params)})))))})) + +(defn- format-var [x & [opts]] + (let [c (name x)] + (cond (= \% (first c)) + (let [[f & args] (str/split (subs c 1) #"\.")] + ;; TODO: this does not quote arguments -- does that matter? + [(str f "(" (str/join "," args) ")")]) + (= \? (first c)) + ["?" (->param (keyword (subs c 1)))] + :else + [(format-entity x opts)]))) (defn- format-entity-alias [x] (cond (sequential? x) @@ -151,7 +163,9 @@ (into params'))) (or (keyword? x) (symbol? x)) - [(format-entity x opts)] + (if aliased? + [(format-entity x opts)] + (format-var x opts)) (and aliased? (string? x)) [(format-entity x opts)] @@ -419,7 +433,7 @@ ;:order-by 190 ;:limit 200 ;:offset 210 - :lock 215 + ;:lock 215 ;:values 220 :query-values 230}) ;; :on-conflict -- https://www.postgresqltutorial.com/postgresql-upsert/ @@ -517,11 +531,18 @@ :not (fn [_ [x]] (let [[sql & params] (format-expr x)] - (into [(str "NOT " sql)] params)))})) + (into [(str "NOT " sql)] params))) + :param + (fn [_ [k]] + ["?" (->param k)]) + :raw + ;; TODO: only supports single raw string right now + (fn [_ [s]] + [s])})) (defn format-expr [x & [{:keys [nested?] :as opts}]] (cond (or (keyword? x) (symbol? x)) - [(format-entity x opts)] + (format-var x opts) (map? x) (format-dsl x (assoc opts :nested? true)) diff --git a/src/readme.clj b/src/readme.clj index bc8136f..871f71a 100644 --- a/src/readme.clj +++ b/src/readme.clj @@ -317,8 +317,8 @@ WHERE kind <> ? (-> (select :id) (from :foo) (where [:= :a :?baz]) - (sql/format :params {:baz "BAZ"})) -=> ["SELECT id FROM foo WHERE a = ?" "BAZ"] + (sql/format {:params {:baz "BAZ"}})) +=> ["SELECT id FROM foo WHERE (a = ?)" "BAZ"] ) From 663233538470024d1783ec7b1cb5c9d43589c831 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 2 Oct 2020 13:24:44 -0700 Subject: [PATCH 043/254] Add nesting support in expressions and the DSL --- src/honey/sql.cljc | 15 +++++++++++---- src/honey/sql/helpers.cljc | 1 + 2 files changed, 12 insertions(+), 4 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0c10921..3a48576 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -16,7 +16,7 @@ (declare clause-format) (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." - [:with :with-recursive :intersect :union :union-all :except :except-all + [:nest :with :with-recursive :intersect :union :union-all :except :except-all :select :insert-into :update :delete :delete-from :truncate :columns :composite :set :from :join :left-join :right-join :inner-join :outer-join :full-join @@ -361,7 +361,8 @@ (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:with #'format-with + (atom {:nest (fn [_ x] (format-expr x)) + :with #'format-with :with-recursive #'format-with :intersect #'format-on-set-op :union #'format-on-set-op @@ -516,8 +517,11 @@ (into params-b)))) :cast (fn [_ [x type]] - (let [[sql & params] (format-expr x)] - (into [(str "CAST(" sql " AS " (sql-kw type) ")")] params))) + (let [[sql & params] (format-expr x) + [sql' & params'] (format-expr type)] + (-> [(str "CAST(" sql " AS " sql' ")")] + (into params) + (into params')))) :default (fn [_ []] ["DEFAULT"]) @@ -528,6 +532,9 @@ (fn [_ [n units]] (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params))) + :nest + (fn [_ [x]] + (format-expr x {:nested? true})) :not (fn [_ [x]] (let [[sql & params] (format-expr x)] diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index c78ed1a..8986639 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -26,6 +26,7 @@ (helper-merge data k args)) (helper-merge {} k args))) +(defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) (defn intersect [& args] (generic :intersect args)) From 04724df814b0c451eadb9ded3959758638130ed4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 2 Oct 2020 13:43:44 -0700 Subject: [PATCH 044/254] Implement :lift special syntax --- src/honey/sql.cljc | 3 +++ 1 file changed, 3 insertions(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3a48576..a77b9ab 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -532,6 +532,9 @@ (fn [_ [n units]] (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params))) + :lift + (fn [_ [x]] + ["?" x]) :nest (fn [_ [x]] (format-expr x {:nested? true})) From 8db28e964d49ecfa1c1c2fb81a5c9eb21d3a1815 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 7 Oct 2020 22:27:13 -0700 Subject: [PATCH 045/254] Update deps-deploy group ID (and version) --- deps.edn | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/deps.edn b/deps.edn index fd1fedc..a6bd36e 100644 --- a/deps.edn +++ b/deps.edn @@ -22,7 +22,7 @@ :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.117"}} :main-opts ["-m" "hf.depstar.jar" "honeysql.jar"]} - :install {:extra-deps {deps-deploy/deps-deploy {:mvn/version "0.0.9"}} + :install {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} :main-opts ["-m" "deps-deploy.deps-deploy" "install" "honeysql.jar"]} - :deploy {:extra-deps {deps-deploy/deps-deploy {:mvn/version "0.0.9"}} + :deploy {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} :main-opts ["-m" "deps-deploy.deps-deploy" "deploy" "honeysql.jar"]}}} From e4e8dd33421aaca7832213794541f43bb1f52556 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 7 Oct 2020 23:04:52 -0700 Subject: [PATCH 046/254] Latest test-runner SHA --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index a6bd36e..4fa0cbf 100644 --- a/deps.edn +++ b/deps.edn @@ -11,7 +11,7 @@ :runner {:extra-deps {com.cognitect/test-runner {:git/url "https://github.com/cognitect-labs/test-runner" - :sha "f7ef16dc3b8332b0d77bc0274578ad5270fbfedd"}} + :sha "b6b3193fcc42659d7e46ecd1884a228993441182"}} :main-opts ["-m" "cognitect.test-runner" "-d" "test"]} :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.7.0"}} From 40828b2c57fb36488b9a8351610d62151acd711c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 8 Oct 2020 22:29:10 -0700 Subject: [PATCH 047/254] Update to latest depstar; latest CLI --- .github/workflows/test.yml | 2 +- deps.edn | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index ca8f69b..bded007 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -17,6 +17,6 @@ jobs: - name: Setup Clojure uses: DeLaGuardo/setup-clojure@2.0 with: - tools-deps: '1.10.1.536' + tools-deps: '1.10.1.708' - name: Run Tests run: sh run-tests.sh all diff --git a/deps.edn b/deps.edn index 4fa0cbf..72bf9ec 100644 --- a/deps.edn +++ b/deps.edn @@ -20,7 +20,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.117"}} + :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.126"}} :main-opts ["-m" "hf.depstar.jar" "honeysql.jar"]} :install {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} :main-opts ["-m" "deps-deploy.deps-deploy" "install" "honeysql.jar"]} From 0255307aafe48aeb4b0ef5949f7f6f5c2e80d031 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 14:53:13 -0700 Subject: [PATCH 048/254] Bump to latest depstar --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index 72bf9ec..93e04bc 100644 --- a/deps.edn +++ b/deps.edn @@ -20,7 +20,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.126"}} + :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.128"}} :main-opts ["-m" "hf.depstar.jar" "honeysql.jar"]} :install {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} :main-opts ["-m" "deps-deploy.deps-deploy" "install" "honeysql.jar"]} From 0c7ce43381fd04eccae10529764a1d3a00c79fe6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 21:30:45 -0700 Subject: [PATCH 049/254] Address #279 by treating UNION expressions as nested --- src/honey/sql.cljc | 2 +- test/honey/sql_test.cljc | 20 ++++++++++---------- 2 files changed, 11 insertions(+), 11 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a77b9ab..c783d3f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -180,7 +180,7 @@ (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #'format-dsl xs))] + (map #(format-dsl % {:nested? true}) xs))] (into [(str/join (str " " (sql-kw k) " ") sqls)] params))) (defn- format-expr-list [xs & [opts]] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 915e4a4..5adf001 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -169,30 +169,30 @@ ;; ORDER BY foo ASC (is (= (format {:union [{:select [:foo] :from [:bar1]} {:select [:foo] :from [:bar2]}]}) - ["SELECT foo FROM bar1 UNION SELECT foo FROM bar2"])) + ["(SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])) (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]]}]]}) - ["WITH bar (spam, eggs) AS (VALUES (?, ?), (?, ?), (?, ?)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2" + ["WITH bar (spam, eggs) AS (VALUES (?, ?), (?, ?), (?, ?)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)" 1 2 3 4 5 6])))) (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"]))) + ["(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"]))) + ["(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"]))) + ["(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" @@ -206,7 +206,7 @@ :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])))) + ["(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" @@ -238,14 +238,14 @@ {: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]))) + ["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]))) + ["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 -- fail: parameterizer" @@ -261,7 +261,7 @@ :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"])))) + ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])))) (deftest inline-was-parameterizer-none (testing "array parameter" @@ -278,7 +278,7 @@ :with [[[:bar {:columns [:spam :eggs]}] {:values (mapv #(mapv vector (repeat :inline) %) [[1 2] [3 4] [5 6]])}]]}) - ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) SELECT foo FROM bar1 UNION SELECT foo FROM bar2"])))) + ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])))) #_(defmethod parameterize :single-quote [_ value pname] (str \' value \')) #_(defmethod parameterize :mysql-fill [_ value pname] "?") From 97a378211235ebc14824321288b106c5399ae688 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 21:52:18 -0700 Subject: [PATCH 050/254] Support :inline option This is similar to `:parameterizer :none` (but better). --- src/honey/sql.cljc | 32 ++++++++++++++++++++++---------- test/honey/sql_test.cljc | 34 ++++++++++++++++------------------ 2 files changed, 38 insertions(+), 28 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index c783d3f..633cea4 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -64,6 +64,7 @@ ;; functions harder than necessary: (def ^:private ^:dynamic *clause-order* default-clause-order) (def ^:private ^:dynamic *quoted* nil) +(def ^:private ^:dynamic *inline* nil) ;; clause helpers @@ -613,9 +614,9 @@ (str " " (first sqls)) (str "(" (str/join ", " sqls) ")")))] params))) - (into [(str "(" (str/join ", " - (repeat (count x) "?")) ")")] - x))) + (if *inline* + [(str "(" (str/join ", " (map #'sqlize-value x)) ")")] + (into [(str "(" (str/join ", " (repeat (count x) "?")) ")")] x)))) (or (true? x) (false? x)) ; because (boolean? x) requires Clojure 1.9+ [(upper-case (str x))] @@ -624,7 +625,9 @@ ["NULL"] :else - ["?" x])) + (if *inline* + [(sqlize-value x)] + ["?" x]))) (defn- check-dialect [dialect] (when-not (contains? dialects dialect) @@ -652,6 +655,8 @@ (f @base-clause-order) @current-clause-order) @current-clause-order) + *inline* (when (contains? opts :inline) + (:inline opts)) *quoted* (if (contains? opts :quoted) (:quoted opts) dialect?)] @@ -736,11 +741,18 @@ (format {:select [:*] :from [:table] :group-by [:foo :bar]} {}) (format {:select [:*] :from [:table] :group-by [[:date :bar]]} {}) (format {:select [:*] :from [:table] :order-by [[:foo :desc] :bar]} {}) - (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) - (println (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {:pretty? true})) - (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) + (format {:select [:*] :from [:table] + :order-by [[[:date :expiry] :desc] :bar]} {}) + (println (format {:select [:*] :from [:table] + :order-by [[[:date :expiry] :desc] :bar]} {:pretty? true})) + (format {:select [:*] :from [:table] + :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) - (format {:select [:*] :from [:table] :where [:= :id (int 1)]} {:dialect :mysql}) - (map fn? (format {:select [:*] :from [:table] :where [:= :id (with-meta (constantly 42) {:foo true})]} {:dialect :mysql})) - (println (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {:pretty? true})) + (format {:select [:*] :from [:table] + :where [:= :id (int 1)]} {:dialect :mysql}) + (map fn? (format {:select [:*] :from [:table] + :where [:= :id (with-meta (constantly 42) {:foo true})]} + {:dialect :mysql})) + (println (format {:select [:*] :from [:table] + :where [:in :id [1 2 3 4]]} {:pretty? true})) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 5adf001..431be52 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -248,11 +248,11 @@ ["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 -- fail: parameterizer" + (testing "array parameter" (is (= (format {:insert-into :foo :columns [:baz] :values [[[:array [1 2 3 4]]]]} - {:parameterizer :none}) + {:inline true}) ["INSERT INTO foo (baz) VALUES (ARRAY[1, 2, 3, 4])"]))) (testing "union complex values -- fail: parameterizer" @@ -260,7 +260,7 @@ {:select [:foo] :from [:bar2]}] :with [[[:bar {:columns [:spam :eggs]}] {:values [[1 2] [3 4] [5 6]]}]]} - {:parameterizer :none}) + {:inline true}) ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])))) (deftest inline-was-parameterizer-none @@ -280,27 +280,25 @@ [[1 2] [3 4] [5 6]])}]]}) ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])))) -#_(defmethod parameterize :single-quote [_ value pname] (str \' value \')) -#_(defmethod parameterize :mysql-fill [_ value pname] "?") - (deftest former-parameterizer-tests-where-and - (testing "should ignore a nil predicate -- fail: postgresql parameterizer" - (is (= (format {:where [:and - [:= :foo "foo"] - [:= :bar "bar"] - nil - [:= :quux "quux"]]} - {:parameterizer :postgresql}) - ["WHERE (foo = ?) AND (bar = $2) AND (quux = $3)" "foo" "bar" "quux"]))) - ;; this is _almost_ what :inline should be doing: - #_(testing "should fill param with single quote" + ;; I have no plans for positional parameters -- I just don't see the point + #_(testing "should ignore a nil predicate -- fail: postgresql parameterizer" (is (= (format {:where [:and [:= :foo "foo"] [:= :bar "bar"] nil [:= :quux "quux"]]} - {:parameterizer :single-quote}) - ["WHERE (foo = 'foo') AND (bar = 'bar') AND (quux = 'quux')" "foo" "bar" "quux"]))) + {:parameterizer :postgresql}) + ["WHERE (foo = ?) AND (bar = $2) AND (quux = $3)" "foo" "bar" "quux"]))) + ;; new :inline option is similar to :parameterizer :none in 1.0 + (testing "should fill param with single quote" + (is (= (format {:where [:and + [:= :foo "foo"] + [:= :bar "bar"] + nil + [:= :quux "quux"]]} + {:inline true}) + ["WHERE (foo = 'foo') AND (bar = 'bar') AND (quux = 'quux')"]))) (testing "should inline params with single quote" (is (= (format {:where [:and [:= :foo [:inline "foo"]] From a83998d35472cc69b31e4e97027e784deaf635bf Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 22:31:55 -0700 Subject: [PATCH 051/254] Documented extension mechanism; updated README Helpers are the next big piece of work. --- README.md | 89 ++++--- src/honey/sql.cljc | 4 +- src/readme.clj | 607 --------------------------------------------- 3 files changed, 58 insertions(+), 642 deletions(-) delete mode 100644 src/readme.clj diff --git a/README.md b/README.md index 3981f49..4657971 100644 --- a/README.md +++ b/README.md @@ -522,58 +522,81 @@ OFFSET ? ## Extensibility -_This needs a rewrite!_ +Any keyword (or symbol) that appears as the first element of a vector will be treated as a generic function unless it is declared to be an operator or "special syntax". Any keyword (or symbol) that appears as a key in a hash map will be treated as a SQL clause -- and must either be built-in or must be registered as new clauses. -You can define your own function handlers for use in `where`: +If your database supports `<=>` as an operator, you can tell HoneySQL about it using the `register-op!` function (which should be called before the first call to `honey.sql/format`): ```clojure -(defmethod fmt/fn-handler "betwixt" [_ field lower upper] - (str (fmt/to-sql field) " BETWIXT " - (fmt/to-sql lower) " AND " (fmt/to-sql upper))) +(sql/register-op! :<=>) +;; default is a binary operator: +(-> (select :a) (where [:<=> :a "foo"]) sql/format) +=> ["SELECT a WHERE a <=> ?" "foo"] +;; you can declare that an operator is variadic: +(sql/register-op! :<=> :variadic? true) +(-> (select :a) (where [:<=> "food" :a "fool"]) sql/format) +=> ["SELECT a WHERE ? <=> a <=> ?" "food" "fool"] +``` +Sometimes you want an operator to ignore `nil` clauses (`:and` and `:or` are declared that way): + +```clojure +(sql/register-op! :<=> :ignore-nil? true) +``` + +Or perhaps your database supports syntax like `a BETWIXT b AND c`, in which case you can use `register-fn!` to tell HoneySQL about it (again, called before the first call to `honey.sql/format`): + +```clojure +;; the formatter will be passed your new operator (function) and a +;; sequence of the arguments provided to it (so you can write any arity ops): +(sql/register-fn! :betwixt + (fn [op [a b c]] + (let [[sql-a & params-a] (sql/format-expr a) + [sql-b & params-b] (sql/format-expr b) + [sql-c & params-c] (sql/format-expr c)] + (-> [(str sql-a " " (sql/sql-kw op) " " + sql-b " AND " sql-c)] + (into params-a) + (into params-b) + (into params-c))))) +;; example usage: (-> (select :a) (where [:betwixt :a 1 10]) sql/format) => ["SELECT a WHERE a BETWIXT ? AND ?" 1 10] ``` -You can also define your own clauses: +You can also register SQL clauses, specifying the keyword, the formatting function, and an existing clause that this new clause should be processed before: ```clojure -;; Takes a MapEntry of the operator & clause data, plus the entire SQL map -(defmethod fmt/format-clause :foobar [[op v] sqlmap] - (str "FOOBAR " (fmt/to-sql v))) -``` -```clojure +;; the formatter will be passed your new clause and the value associated +;; with that clause in the DSL (which is often a sequence but does not +;; need to be -- it can be whatever syntax you desire in the DSL): +(sql/register-clause! :foobar + (fn [clause x] + (let [[sql & params] + (if (keyword? x) + (sql/format-expr x) + (sql/format-dsl x))] + (into [(str (sql/sql-kw clause) " " sql)] params))) + :from) ; SELECT ... FOOBAR ... FROM ... +;; example usage: (sql/format {:select [:a :b] :foobar :baz}) => ["SELECT a, b FOOBAR baz"] -``` -```clojure -(require '[honeysql.helpers :refer [defhelper]]) - -;; Defines a helper function, and allows 'build' to recognize your clause -(defhelper foobar [m args] - (assoc m :foobar (first args))) -``` -```clojure -(-> (select :a :b) (foobar :baz) sql/format) -=> ["SELECT a, b FOOBAR baz"] - +(sql/format {:select [:a :b] :foobar {:where [:= :id 1]}}) +=> ["SELECT a, b FOOBAR WHERE id = ?" 1] ``` -When adding a new clause, you may also need to register it with a specific priority so that it formats correctly, for example: - -```clojure -(fmt/register-clause! :foobar 110) -``` - -If you do implement a clause or function handler for an ANSI SQL, consider submitting a pull request so others can use it, too. For non-standard clauses and/or functions, look for a library that extends `honeysql` for that specific database or create one, if no such library exists. +If you find yourself registering an operator, a function (syntax), or a new clause, consider submitting a [pull request to HoneySQL](https://github.com/seancorfield/honeysql/pulls) so others can use it, too. If it is dialect-specific, let me know in the pull request. ## Why does my parameter get emitted as `()`? +_Need to investigate whether this is still true in 2.0!_ + If you want to use your own datatype as a parameter then the idiomatic approach of implementing `next.jdbc`'s [`SettableParameter`](https://cljdoc.org/d/seancorfield/next.jdbc/CURRENT/api/next.jdbc.prepare#SettableParameter) -or `clojure.java.jdbc`'s [`ISQLValue`](https://clojure.github.io/java.jdbc/#clojure.java.jdbc/ISQLValue) protocol isn't enough as `honeysql` won't correct pass through your datatype, rather it will interpret it incorrectly. +or `clojure.java.jdbc`'s [`ISQLValue`](https://clojure.github.io/java.jdbc/#clojure.java.jdbc/ISQLValue) protocol isn't enough as HoneySQL won't correct pass through your datatype, rather it will interpret it incorrectly. -To teach `honeysql` how to handle your datatype you need to implement [`honeysql.format/ToSql`](https://github.com/seancorfield/honeysql/blob/a9dffec632be62c961be7d9e695d0b2b85732c53/src/honeysql/format.cljc#L94). For example: +_This bit no longer exists:_ + +To teach HoneySQL how to handle your datatype you need to implement [`honeysql.format/ToSql`](https://github.com/seancorfield/honeysql/blob/a9dffec632be62c961be7d9e695d0b2b85732c53/src/honeysql/format.cljc#L94). For example: ``` clojure ;; given: (defrecord MyDateWrapper [...] @@ -599,7 +622,7 @@ To teach `honeysql` how to handle your datatype you need to implement [`honeysql ## Extensions -* [For PostgreSQL-specific extensions falling outside of ANSI SQL](https://github.com/nilenso/honeysql-postgres) +* [For PostgreSQL-specific extensions falling outside of ANSI SQL](https://github.com/nilenso/honeysql-postgres) -- these will all be core in 2.0! ## License diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 633cea4..1d3511f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -82,7 +82,7 @@ #?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US)))) :cljs str/upper-case)) -(defn- sql-kw [k] +(defn sql-kw [k] (-> k (name) (upper-case) (str/replace "-" " "))) (defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] @@ -444,7 +444,7 @@ ;; ;do-nothing ;:returning -(defn- format-dsl [x & [{:keys [aliased? nested? pretty?]}]] +(defn format-dsl [x & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] (if-let [xs (or (k x) (let [s (symbol (name k))] (get x s)))] diff --git a/src/readme.clj b/src/readme.clj deleted file mode 100644 index 871f71a..0000000 --- a/src/readme.clj +++ /dev/null @@ -1,607 +0,0 @@ -(ns readme (:require [seancorfield.readme])) - - - - - - - - - - - - - - - - - - - - - - - -(seancorfield.readme/defreadme readme-25 -(refer-clojure :exclude '[for group-by set update]) -(require '[honey.sql :as sql] - ;; caution: this overwrites for, group-by, set, and update - '[honey.sql.helpers :refer :all :as helpers]) -) - - - -(seancorfield.readme/defreadme readme-34 -(def sqlmap {:select [:a :b :c] - :from [:foo] - :where [:= :f.a "baz"]}) -) - - - - - - - -(seancorfield.readme/defreadme readme-46 -(sql/format sqlmap) -=> ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] -) - - - - - - - - - - - - - - - - - -(seancorfield.readme/defreadme readme-67 -(def q-sqlmap {:select [:foo/a :foo/b :foo/c] - :from [:foo] - :where [:= :foo/a "baz"]}) -(sql/format q-sqlmap) -=> ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] -) - - - - - - - -(seancorfield.readme/defreadme readme-81 -(-> (select :a :b :c) - (from :foo) - (where [:= :f.a "baz"])) -) - - - -(seancorfield.readme/defreadme readme-89 -(= (-> (select :*) (from :foo)) - (-> (from :foo) (select :*))) -=> true -) - - - -(seancorfield.readme/defreadme readme-97 -(-> sqlmap (select :d)) -=> '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} -) - - - -(seancorfield.readme/defreadme readme-104 -(-> sqlmap - (dissoc :select) - (select :*) - (where [:> :b 10]) - sql/format) -=> ["SELECT * FROM foo WHERE (f.a = ?) AND (b > ?)" "baz" 10] -) - - - -(seancorfield.readme/defreadme readme-115 -(-> (select :*) - (from :foo) - (where [:= :a 1] [:< :b 100]) - sql/format) -=> ["SELECT * FROM foo WHERE (a = ?) AND (b < ?)" 1 100] -) - - - - -(seancorfield.readme/defreadme readme-126 -(-> (select :a [:b :bar] :c [:d :x]) - (from [:foo :quux]) - (where [:= :quux.a 1] [:< :bar 100]) - sql/format) -=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ?) AND (bar < ?)" 1 100] -) - - - - - - - - - - -(seancorfield.readme/defreadme readme-143 -(-> (insert-into :properties) - (columns :name :surname :age) - (values - [["Jon" "Smith" 34] - ["Andrew" "Cooper" 12] - ["Jane" "Daniels" 56]]) - (sql/format {:pretty? true})) -=> [" -INSERT INTO properties (name, surname, age) -VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) -" -"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] -) - - - - - -(seancorfield.readme/defreadme readme-162 -(-> (insert-into :properties) - (values [{:name "John" :surname "Smith" :age 34} - {:name "Andrew" :surname "Cooper" :age 12} - {:name "Jane" :surname "Daniels" :age 56}]) - (sql/format {:pretty? true})) -=> [" -INSERT INTO properties (name, surname, age) -VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) -" -"John" "Smith" 34 -"Andrew" "Cooper" 12 -"Jane" "Daniels" 56] -) - - - - - -(seancorfield.readme/defreadme readme-181 -(let [user-id 12345 - role-name "user"] - (-> (insert-into :user_profile_to_role) - (values [{:user_profile_id user-id - :role_id (-> (select :id) - (from :role) - (where [:= :name role-name]))}]) - (sql/format {:pretty? true}))) - -=> [" -INSERT INTO user_profile_to_role (user_profile_id, role_id) -VALUES (?, (SELECT id FROM role WHERE name = ?)) -" -12345 -"user"] -) - -(seancorfield.readme/defreadme readme-199 -(-> (select :*) - (from :foo) - (where [:in :foo.a (-> (select :a) (from :bar))]) - sql/format) -=> ["SELECT * FROM foo WHERE (foo.a in (SELECT a FROM bar))"] -) - - - - - -(seancorfield.readme/defreadme readme-211 -(-> (insert-into :comp_table) - (columns :name :comp_column) - (values - [["small" (composite 1 "inch")] - ["large" (composite 10 "feet")]]) - (sql/format {:pretty? true})) -=> [" -INSERT INTO comp_table (name, comp_column) -VALUES (?, (?, ?)), (?, (?, ?)) -" -"small" 1 "inch" "large" 10 "feet"] -) - - - - - -(seancorfield.readme/defreadme readme-229 -(-> (helpers/update :films) - (set {:kind "dramatic" - :watched [:+ :watched 1]}) - (where [:= :kind "drama"]) - (sql/format {:pretty? true})) -=> [" -UPDATE films SET kind = ?, watched = (watched + ?) -WHERE kind = ? -" -"dramatic" -1 -"drama"] -) - - - - - - - - - - - - -(seancorfield.readme/defreadme readme-255 -(-> (delete-from :films) - (where [:<> :kind "musical"]) - (sql/format)) -=> ["DELETE FROM films WHERE kind <> ?" "musical"] -) - - - -(seancorfield.readme/defreadme readme-264 -(-> (delete [:films :directors]) - (from :films) - (join :directors [:= :films.director_id :directors.id]) - (where [:<> :kind "musical"]) - (sql/format {:pretty? true})) -=> [" -DELETE films, directors -FROM films -INNER JOIN directors ON films.director_id = directors.id -WHERE kind <> ? -" -"musical"] -) - - - -(seancorfield.readme/defreadme readme-281 -(-> (truncate :films) - (sql/format)) -=> ["TRUNCATE films"] -) - - - - - -(seancorfield.readme/defreadme readme-291 -(sql/format {:union [(-> (select :*) (from :foo)) - (-> (select :*) (from :bar))]}) -=> ["SELECT * FROM foo UNION SELECT * FROM bar"] -) - - - - - -(seancorfield.readme/defreadme readme-301 -(-> (select :%count.*) (from :foo) sql/format) -=> ["SELECT count(*) FROM foo"] -) -(seancorfield.readme/defreadme readme-305 -(-> (select :%max.id) (from :foo) sql/format) -=> ["SELECT max(id) FROM foo"] -) - - - - - - - -(seancorfield.readme/defreadme readme-316 -(-> (select :id) - (from :foo) - (where [:= :a :?baz]) - (sql/format {:params {:baz "BAZ"}})) -=> ["SELECT id FROM foo WHERE (a = ?)" "BAZ"] -) - - - - - - -(seancorfield.readme/defreadme readme-329 -(def call-qualify-map - (-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]]) - (from :foo) - (where [:= :a [:param :baz]] [:= :b [:inline 42]]))) -) -(seancorfield.readme/defreadme readme-335 -call-qualify-map -=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] - :from (:foo) - :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} -) -(seancorfield.readme/defreadme readme-341 -(sql/format call-qualify-map {:params {:baz "BAZ"}}) -=> ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] -) - - - - - - -(seancorfield.readme/defreadme readme-351 -(-> (insert-into :sample) - (values [{:location [:ST_SetSRID - [:ST_MakePoint 0.291 32.621] - [:cast 4325 :integer]]}]) - (sql/format {:pretty? true})) -=> [" -INSERT INTO sample (location) -VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) -" -0.291 32.621 4326] -) - - - - - - - - - - - - - - -(seancorfield.readme/defreadme readme-377 -(-> (select :*) - (from :foo) - (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) - (sql/format {:foo 5})) -=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] -) - -(seancorfield.readme/defreadme readme-385 -(-> (select :*) - (from :foo) - (where [:< :expired_at [:raw ["now() - '" [:param :t] " seconds'"]]]) - (sql/format {:t 5})) -=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] -) - - - - - - - - - - -(seancorfield.readme/defreadme readme-402 -(-> (select :foo.a) - (from :foo) - (where [:= :foo.a "baz"]) - (sql/format {:dialect :mysql})) -=> ["SELECT `foo`.`a` FROM `foo` WHERE `foo`.`a` = ?" "baz"] -) - - - - - - - - - - - - - - - - - -(seancorfield.readme/defreadme readme-426 -(-> (select :foo.a) - (from :foo) - (where [:= :foo.a "baz"]) - (for :update) - (format)) -=> ["SELECT foo.a FROM foo WHERE (foo.a = ?) FOR UPDATE" "baz"] -) - - - -(seancorfield.readme/defreadme readme-437 -(sql/format {:select [:*] :from :foo - :where [:= :name [:inline "Jones"]] - :lock [:in-share-mode]} - {:dialect :mysql :quoted false}) -=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] -) - - -(seancorfield.readme/defreadme readme-446 -(sql/format - {:select [:f.foo-id :f.foo-name] - :from [[:foo-bar :f]] - :where [:= :f.foo-id 12345]} - {:allow-dashed-names? true ; not implemented yet - :quoted true}) -=> ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] -) - - - - - -(seancorfield.readme/defreadme readme-460 -(def big-complicated-map - (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] - [[:now]] [[:raw "@x := 10"]]) - #_(modifiers :distinct) ; this is not implemented yet - (from [:foo :f] [:baz :b]) - (join :draq [:= :f.b :draq.x]) - (left-join [:clod :c] [:= :f.a :c.d]) - (right-join :bock [:= :bock.z :c.e]) - (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] - [:< 1 2 3] - [:in :f.e [1 [:param :param2] 3]] - [:between :f.e 10 20]]) - (group-by :f.a :c.e) - (having [:< 0 :f.e]) - (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) - (limit 50) - (offset 10))) -) -(seancorfield.readme/defreadme readme-480 -big-complicated-map -=> {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] - [[:now]] [[:raw "@x := 10"]]] - :modifiers [:distinct] - :from [[:foo :f] [:baz :b]] - :join [:draq [:= :f.b :draq.x]] - :left-join [[:clod :c] [:= :f.a :c.d]] - :right-join [:bock [:= :bock.z :c.e]] - :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] - [:< 1 2 3] - [:in :f.e [1 [:param :param2] 3]] - [:between :f.e 10 20]] - :group-by [:f.a :c.e] - :having [:< 0 :f.e] - :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] - :limit 50 - :offset 10} -) -(seancorfield.readme/defreadme readme-500 -(sql/format big-complicated-map {:param1 "gabba" :param2 2}) -=> [" -SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 -FROM foo f, baz b -INNER JOIN draq ON f.b = draq.x -LEFT JOIN clod c ON f.a = c.d -RIGHT JOIN bock ON bock.z = c.e -WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) -GROUP BY f.a, c.e -HAVING ? < f.e -ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST -LIMIT ? -OFFSET ? -" -"bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] -) -(seancorfield.readme/defreadme readme-517 -;; Printable and readable -(= big-complicated-map (read-string (pr-str big-complicated-map))) -=> true -) - - - - - - - -(seancorfield.readme/defreadme readme-529 -(defmethod fmt/fn-handler "betwixt" [_ field lower upper] - (str (fmt/to-sql field) " BETWIXT " - (fmt/to-sql lower) " AND " (fmt/to-sql upper))) - -(-> (select :a) (where [:betwixt :a 1 10]) sql/format) -=> ["SELECT a WHERE a BETWIXT ? AND ?" 1 10] -) - - - -(seancorfield.readme/defreadme readme-540 -;; Takes a MapEntry of the operator & clause data, plus the entire SQL map -(defmethod fmt/format-clause :foobar [[op v] sqlmap] - (str "FOOBAR " (fmt/to-sql v))) -) -(seancorfield.readme/defreadme readme-545 -(sql/format {:select [:a :b] :foobar :baz}) -=> ["SELECT a, b FOOBAR baz"] -) -(seancorfield.readme/defreadme readme-549 -(require '[honeysql.helpers :refer [defhelper]]) - -;; Defines a helper function, and allows 'build' to recognize your clause -(defhelper foobar [m args] - (assoc m :foobar (first args))) -) -(seancorfield.readme/defreadme readme-556 -(-> (select :a :b) (foobar :baz) sql/format) -=> ["SELECT a, b FOOBAR baz"] - -) - - - -(seancorfield.readme/defreadme readme-564 -(fmt/register-clause! :foobar 110) -) - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - From 98b18bbb6e7b7a71fdcd6fecea6a61f2097ea53c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 23:05:05 -0700 Subject: [PATCH 052/254] Fix where/having helpers; add select-distinct --- README.md | 10 ++--- src/honey/sql.cljc | 79 +++++++++++++++++++------------------- src/honey/sql/helpers.cljc | 28 ++++++++++---- 3 files changed, 64 insertions(+), 53 deletions(-) diff --git a/README.md b/README.md index 4657971..5a37ea0 100644 --- a/README.md +++ b/README.md @@ -459,9 +459,8 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify ```clojure (def big-complicated-map - (-> (select :f.* :b.baz :c.quux [:b.bla "bla-bla"] - [[:now]] [[:raw "@x := 10"]]) - #_(modifiers :distinct) ; this is not implemented yet + (-> (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"] + [[:now]] [[:raw "@x := 10"]]) (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) @@ -479,9 +478,8 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify ``` ```clojure big-complicated-map -=> {:select [:f.* :b.baz :c.quux [:b.bla "bla-bla"] - [[:now]] [[:raw "@x := 10"]]] - :modifiers [:distinct] +=> {:select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] + [[:now]] [[:raw "@x := 10"]]] :from [[:foo :f] [:baz :b]] :join [:draq [:= :f.b :draq.x]] :left-join [[:clod :c] [:= :f.a :c.d]] diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1d3511f..06f06a7 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -17,7 +17,7 @@ (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." [:nest :with :with-recursive :intersect :union :union-all :except :except-all - :select :insert-into :update :delete :delete-from :truncate + :select :select-distinct :insert-into :update :delete :delete-from :truncate :columns :composite :set :from :join :left-join :right-join :inner-join :outer-join :full-join :cross-join @@ -362,44 +362,45 @@ (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:nest (fn [_ x] (format-expr x)) - :with #'format-with - :with-recursive #'format-with - :intersect #'format-on-set-op - :union #'format-on-set-op - :union-all #'format-on-set-op - :except #'format-on-set-op - :except-all #'format-on-set-op - :select #'format-selects - :insert-into #'format-insert - :update #'format-selector - :delete #'format-selects - :delete-from #'format-selector - :truncate #'format-selector - :columns #'format-columns - :composite #'format-columns - :set #'format-set-exprs - :from #'format-selects - :join #'format-join - :left-join #'format-join - :right-join #'format-join - :inner-join #'format-join - :outer-join #'format-join - :full-join #'format-join - :cross-join #'format-selects - :where #'format-on-expr - :group-by #'format-group-by - :having #'format-on-expr - :order-by #'format-order-by - :limit #'format-on-expr - :offset #'format-on-expr - :for #'format-lock-strength - :values #'format-values - :on-conflict #'format-on-conflict - :on-constraint #'format-selector - :do-nothing (fn [k _] (vector (sql-kw k))) - :do-update-set #'format-do-update-set - :returning #'format-selects})) + (atom {:nest (fn [_ x] (format-expr x)) + :with #'format-with + :with-recursive #'format-with + :intersect #'format-on-set-op + :union #'format-on-set-op + :union-all #'format-on-set-op + :except #'format-on-set-op + :except-all #'format-on-set-op + :select #'format-selects + :select-distinct #'format-selects + :insert-into #'format-insert + :update #'format-selector + :delete #'format-selects + :delete-from #'format-selector + :truncate #'format-selector + :columns #'format-columns + :composite #'format-columns + :set #'format-set-exprs + :from #'format-selects + :join #'format-join + :left-join #'format-join + :right-join #'format-join + :inner-join #'format-join + :outer-join #'format-join + :full-join #'format-join + :cross-join #'format-selects + :where #'format-on-expr + :group-by #'format-group-by + :having #'format-on-expr + :order-by #'format-order-by + :limit #'format-on-expr + :offset #'format-on-expr + :for #'format-lock-strength + :values #'format-values + :on-conflict #'format-on-conflict + :on-constraint #'format-selector + :do-nothing (fn [k _] (vector (sql-kw k))) + :do-update-set #'format-do-update-set + :returning #'format-selects})) (assert (= (set @base-clause-order) (set @current-clause-order) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 8986639..21641bf 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -8,13 +8,19 @@ (defn- default-merge [current args] (into (vec current) args)) +(defn- and-merge + [current args] + (let [merged (default-merge current args)] + (cond (= 1 (count merged)) + (vec (first merged)) + (= :and (first merged)) + merged + :else + (into [:and] merged)))) + (def ^:private special-merges - {:where (fn [current args] - (if (= :and (first (first args))) - (default-merge current args) - (-> [:and] - (into current) - (into args))))}) + {:where #'and-merge + :having #'and-merge}) (defn- helper-merge [data k args] (let [merge-fn (special-merges k default-merge)] @@ -26,6 +32,11 @@ (helper-merge data k args)) (helper-merge {} k args))) +(defn- generic-1 [k [data arg]] + (if (map? data) + (assoc data k arg) + (assoc {} k data))) + (defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) @@ -35,6 +46,7 @@ (defn except [& args] (generic :except args)) (defn except-all [& args] (generic :except-all args)) (defn select [& args] (generic :select args)) +(defn select-distinct [& args] (generic :select-distinct args)) (defn insert-into [& args] (generic :insert-into args)) (defn update [& args] (generic :update args)) (defn delete [& args] (generic :delete args)) @@ -55,8 +67,8 @@ (defn group-by [& args] (generic :group-by args)) (defn having [& args] (generic :having args)) (defn order-by [& args] (generic :order-by args)) -(defn limit [& args] (generic :limit args)) -(defn offset [& args] (generic :offset args)) +(defn limit [& args] (generic-1 :limit args)) +(defn offset [& args] (generic-1 :offset args)) (defn for [& args] (generic :for args)) (defn values [& args] (generic :values args)) (defn on-conflict [& args] (generic :on-conflict args)) From 15ace00e49400043f6e4d45b329e7d783c74f9d3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 23:58:38 -0700 Subject: [PATCH 053/254] Fix string alias (should quote) --- src/honey/sql.cljc | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 06f06a7..5ebaf27 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -86,7 +86,9 @@ (-> k (name) (upper-case) (str/replace "-" " "))) (defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] - (let [q (if *quoted* (:quote *dialect*) identity) + (let [q (if (or *quoted* (string? x)) + (:quote *dialect*) + identity) [t c] (if-let [n (when-not (or drop-ns? (string? x)) (namespace x))] [n (name x)] From d04d9f600aa59fe25963c37dccc4141664d808f5 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 23:58:55 -0700 Subject: [PATCH 054/254] Fix VALUES with multiple hash maps --- src/honey/sql.cljc | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5ebaf27..113fece 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -310,7 +310,7 @@ (let [cols (keys (first xs)) [sqls params] (reduce (fn [[sql params] [sqls' params']] - [(conj sql (str/join ", " sqls')) + [(conj sql (str "(" (str/join ", " sqls') ")")) (if params' (into params params') params')]) [[] []] (map (fn [m] @@ -320,7 +320,9 @@ (str/join ", " (map #(format-entity % {:drop-ns? true}) cols)) ") " - (sql-kw k) " (" (str/join ", " sqls) ")")] + (sql-kw k) + " " + (str/join ", " sqls))] params)) :else From 9da83b5e1bb04dbb9e1fbfbed061baebc5c2da0c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 23:59:30 -0700 Subject: [PATCH 055/254] Fix where merging; fix single-arg helpers --- src/honey/sql/helpers.cljc | 25 +++++++++++++------------ 1 file changed, 13 insertions(+), 12 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 21641bf..911564e 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -10,13 +10,14 @@ (defn- and-merge [current args] - (let [merged (default-merge current args)] - (cond (= 1 (count merged)) - (vec (first merged)) - (= :and (first merged)) - merged - :else - (into [:and] merged)))) + (cond (= :and (first current)) + (default-merge current args) + (seq current) + (default-merge [:and current] args) + (= 1 (count args)) + (vec (first args)) + :else + (default-merge [:and] args))) (def ^:private special-merges {:where #'and-merge @@ -33,7 +34,7 @@ (helper-merge {} k args))) (defn- generic-1 [k [data arg]] - (if (map? data) + (if arg (assoc data k arg) (assoc {} k data))) @@ -49,12 +50,12 @@ (defn select-distinct [& args] (generic :select-distinct args)) (defn insert-into [& args] (generic :insert-into args)) (defn update [& args] (generic :update args)) -(defn delete [& args] (generic :delete args)) +(defn delete [& args] (generic-1 :delete args)) (defn delete-from [& args] (generic :delete-from args)) (defn truncate [& args] (generic :truncate args)) (defn columns [& args] (generic :columns args)) (defn composite [& args] (generic :composite args)) -(defn set [& args] (generic :set args)) +(defn set [& args] (generic-1 :set args)) (defn from [& args] (generic :from args)) (defn join [& args] (generic :join args)) (defn left-join [& args] (generic :left-join args)) @@ -69,8 +70,8 @@ (defn order-by [& args] (generic :order-by args)) (defn limit [& args] (generic-1 :limit args)) (defn offset [& args] (generic-1 :offset args)) -(defn for [& args] (generic :for args)) -(defn values [& args] (generic :values args)) +(defn for [& args] (generic-1 :for args)) +(defn values [& args] (generic-1 :values args)) (defn on-conflict [& args] (generic :on-conflict args)) (defn on-constraint [& args] (generic :on-constraint args)) (defn do-nothing [& args] (generic :do-nothing args)) From 2decf35072780f6b501a4b59db0fe761556217c3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Oct 2020 23:59:43 -0700 Subject: [PATCH 056/254] Fix most of the README formatting --- README.md | 57 +++++++++++++++++++++++++--------------------- src/honey/sql.cljc | 2 +- 2 files changed, 32 insertions(+), 27 deletions(-) diff --git a/README.md b/README.md index 5a37ea0..14af7e5 100644 --- a/README.md +++ b/README.md @@ -96,7 +96,7 @@ When using the vanilla helper functions, repeated clauses will be merged into ex ```clojure (-> sqlmap (select :d)) -=> '{:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} +=> {:from [:foo], :where [:= :f.a "baz"], :select [:a :b :c :d]} ``` If you want to replace a clause, you can `dissoc` the existing clause first, since this is all data: @@ -128,7 +128,7 @@ name and the desired alias: (from [:foo :quux]) (where [:= :quux.a 1] [:< :bar 100]) sql/format) -=> ["SELECT a, b AS bar, c, d AS x FROM foo quux WHERE (quux.a = ?) AND (bar < ?)" 1 100] +=> ["SELECT a, b AS bar, c, d AS x FROM foo AS quux WHERE (quux.a = ?) AND (bar < ?)" 1 100] ``` In particular, note that `(select [:a :b])` means `SELECT a AS b` rather than @@ -149,7 +149,8 @@ then provide a collection of rows, each a collection of column values: ["Jane" "Daniels" 56]]) (sql/format {:pretty? true})) => [" -INSERT INTO properties (name, surname, age) +INSERT INTO properties +(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) " "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] @@ -166,8 +167,8 @@ and the remaining maps *must* have the same set of keys and values: {:name "Jane" :surname "Daniels" :age 56}]) (sql/format {:pretty? true})) => [" -INSERT INTO properties (name, surname, age) -VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +INSERT INTO properties +(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) " "John" "Smith" 34 "Andrew" "Cooper" 12 @@ -189,8 +190,8 @@ The column values do not have to be literals, they can be nested queries: (sql/format {:pretty? true}))) => [" -INSERT INTO user_profile_to_role (user_profile_id, role_id) -VALUES (?, (SELECT id FROM role WHERE name = ?)) +INSERT INTO user_profile_to_role +(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?)) " 12345 "user"] @@ -201,7 +202,7 @@ VALUES (?, (SELECT id FROM role WHERE name = ?)) (from :foo) (where [:in :foo.a (-> (select :a) (from :bar))]) sql/format) -=> ["SELECT * FROM foo WHERE (foo.a in (SELECT a FROM bar))"] +=> ["SELECT * FROM foo WHERE foo.a IN (SELECT a FROM bar)"] ``` ### Composite types @@ -216,7 +217,8 @@ Composite types are supported: ["large" (composite 10 "feet")]]) (sql/format {:pretty? true})) => [" -INSERT INTO comp_table (name, comp_column) +INSERT INTO comp_table +(name, comp_column) VALUES (?, (?, ?)), (?, (?, ?)) " "small" 1 "inch" "large" 10 "feet"] @@ -233,7 +235,8 @@ Updates are possible too: (where [:= :kind "drama"]) (sql/format {:pretty? true})) => [" -UPDATE films SET kind = ?, watched = (watched + ?) +UPDATE films +SET kind = ?, watched = watched + ? WHERE kind = ? " "dramatic" @@ -291,7 +294,7 @@ Queries may be combined within a :union, :union-all, :intersect or :except keywo ```clojure (sql/format {:union [(-> (select :*) (from :foo)) (-> (select :*) (from :bar))]}) -=> ["SELECT * FROM foo UNION SELECT * FROM bar"] +=> ["(SELECT * FROM foo) UNION (SELECT * FROM bar)"] ``` ### Functions @@ -318,7 +321,7 @@ Keywords that begin with `?` are interpreted as bindable parameters: (from :foo) (where [:= :a :?baz]) (sql/format {:params {:baz "BAZ"}})) -=> ["SELECT id FROM foo WHERE (a = ?)" "BAZ"] +=> ["SELECT id FROM foo WHERE a = ?" "BAZ"] ``` ### Miscellaneous @@ -340,7 +343,7 @@ call-qualify-map ``` ```clojure (sql/format call-qualify-map {:params {:baz "BAZ"}}) -=> ["SELECT foo(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] +=> ["SELECT FOO(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ``` #### PostGIS @@ -355,10 +358,10 @@ have a lot of function calls needed in code: [:cast 4325 :integer]]}]) (sql/format {:pretty? true})) => [" -INSERT INTO sample (location) -VALUES (ST_SetSRID(ST_MakePoint(?, ?), CAST(? AS integer))) +INSERT INTO sample +(location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS integer))) " -0.291 32.621 4326] +0.291 32.621 4325] ``` #### Raw SQL fragments @@ -428,8 +431,8 @@ If `` and `` are both omitted, you may also omit the `[`..`]` (from :foo) (where [:= :foo.a "baz"]) (for :update) - (format)) -=> ["SELECT foo.a FROM foo WHERE (foo.a = ?) FOR UPDATE" "baz"] + (sql/format)) +=> ["SELECT foo.a FROM foo WHERE foo.a = ? FOR UPDATE" "baz"] ``` If the `:mysql` dialect is selected, an additional locking clause is available: @@ -450,7 +453,7 @@ To be able to use dashes in quoted names, you can pass ```:allow-dashed-names tr :where [:= :f.foo-id 12345]} {:allow-dashed-names? true ; not implemented yet :quoted true}) -=> ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] +=> ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" AS \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] ``` ### Big, complicated example @@ -467,7 +470,7 @@ Here's a big, complicated query. Note that Honey SQL makes no attempt to verify (right-join :bock [:= :bock.z :c.e]) (where [:or [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] - [:< 1 2 3] + [:and [:< 1 2] [:< 2 3]] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) (group-by :f.a :c.e) @@ -486,7 +489,7 @@ big-complicated-map :right-join [:bock [:= :bock.z :c.e]] :where [:or [:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]] - [:< 1 2 3] + [:and [:< 1 2] [:< 2 3]] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]] :group-by [:f.a :c.e] @@ -496,14 +499,16 @@ big-complicated-map :offset 10} ``` ```clojure -(sql/format big-complicated-map {:param1 "gabba" :param2 2}) +(sql/format big-complicated-map + {:params {:param1 "gabba" :param2 2} + :pretty? true}) => [" -SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 -FROM foo f, baz b +SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 +FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x -LEFT JOIN clod c ON f.a = c.d +LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e -WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) +WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a, c.e HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 113fece..472f624 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -587,7 +587,7 @@ _ (when (seq y) (throw (ex-info (str "only binary " op - "is supported") + " is supported") {:expr x}))) [s1 & p1] (format-expr a {:nested? true}) [s2 & p2] (format-expr b {:nested? true}) From ccd5447a092d7a35913b388003f01bb1722948c3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 11:33:18 -0700 Subject: [PATCH 057/254] Format sequential values as full SQL expressions --- README.md | 2 +- src/honey/sql.cljc | 10 +++++++--- 2 files changed, 8 insertions(+), 4 deletions(-) diff --git a/README.md b/README.md index 14af7e5..9d6d7fb 100644 --- a/README.md +++ b/README.md @@ -511,7 +511,7 @@ RIGHT JOIN bock ON bock.z = c.e WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a, c.e HAVING ? < f.e -ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST +ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? " diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 472f624..6cdd51a 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -619,9 +619,8 @@ (str " " (first sqls)) (str "(" (str/join ", " sqls) ")")))] params))) - (if *inline* - [(str "(" (str/join ", " (map #'sqlize-value x)) ")")] - (into [(str "(" (str/join ", " (repeat (count x) "?")) ")")] x)))) + (let [[sqls params] (format-expr-list x)] + (into [(str "(" (str/join ", " sqls) ")")] params)))) (or (true? x) (false? x)) ; because (boolean? x) requires Clojure 1.9+ [(upper-case (str x))] @@ -760,4 +759,9 @@ {:dialect :mysql})) (println (format {:select [:*] :from [:table] :where [:in :id [1 2 3 4]]} {:pretty? true})) + (println (format {:select [:*] :from [:table] + :where [:and [:in :id [1 [:param :foo]]] + [:= :bar [:param :quux]]]} + {:params {:foo 42 :quux 13} + :pretty? true})) ,) From 796f11c3f42003907d2bc3ab9220d86a86542ca9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 11:42:47 -0700 Subject: [PATCH 058/254] Fix composite by turning it into special syntax --- src/honey/sql.cljc | 8 +++++--- src/honey/sql/helpers.cljc | 7 +++++-- 2 files changed, 10 insertions(+), 5 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 6cdd51a..b1bcc87 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -18,7 +18,7 @@ "The (default) order for known clauses. Can have items added and removed." [:nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :insert-into :update :delete :delete-from :truncate - :columns :composite :set :from + :columns :set :from :join :left-join :right-join :inner-join :outer-join :full-join :cross-join :where :group-by :having :order-by :limit :offset :for :values @@ -382,7 +382,6 @@ :delete-from #'format-selector :truncate #'format-selector :columns #'format-columns - :composite #'format-columns :set #'format-set-exprs :from #'format-selects :join #'format-join @@ -424,7 +423,6 @@ ;:delete-from 80 ;:truncate 85 ;:columns 90 - ;:composite 95 ;; no longer needed/supported :set0 100 ; low-priority set clause ;:from 110 ;:join 120 @@ -528,6 +526,10 @@ (-> [(str "CAST(" sql " AS " sql' ")")] (into params) (into params')))) + :composite + (fn [_ [& args]] + (let [[sqls params] (format-expr-list args)] + (into [(str "(" (str/join ", " sqls) ")")] params))) :default (fn [_ []] ["DEFAULT"]) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 911564e..31c06f2 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -54,7 +54,6 @@ (defn delete-from [& args] (generic :delete-from args)) (defn truncate [& args] (generic :truncate args)) (defn columns [& args] (generic :columns args)) -(defn composite [& args] (generic :composite args)) (defn set [& args] (generic-1 :set args)) (defn from [& args] (generic :from args)) (defn join [& args] (generic :join args)) @@ -78,6 +77,10 @@ (defn do-update-set [& args] (generic :do-update-set args)) (defn returning [& args] (generic :returning args)) +;; helpers that produce non-clause expressions -- must be listed below: +(defn composite [& args] (into [:composite] args)) + #?(:clj - (assert (= (clojure.core/set @@#'h/base-clause-order) + (assert (= (clojure.core/set (conj @@#'h/base-clause-order + :composite)) (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) From 96260901c273340e0fdf1694c122b47837853824 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 14:53:52 -0700 Subject: [PATCH 059/254] All v1 core clauses are implemented now! --- src/honey/sql.cljc | 38 -------------------------------------- 1 file changed, 38 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b1bcc87..80b0691 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -409,44 +409,6 @@ (set @current-clause-order) (set (keys @clause-format)))) -(comment :target - {;:with 20 - ;:with-recursive 30 - ;:intersect 35 - ;:union 40 - ;:union-all 45 - ;:except 47 - ;:select 50 - ;:insert-into 60 - ;:update 70 - ;:delete 75 - ;:delete-from 80 - ;:truncate 85 - ;:columns 90 - ;; no longer needed/supported :set0 100 ; low-priority set clause - ;:from 110 - ;:join 120 - ;:left-join 130 - ;:right-join 140 - ;:full-join 150 - ;:cross-join 152 ; doesn't have on clauses - ;:set 155 - ;; no longer needed/supported :set1 156 ; high-priority set clause (synonym for :set) - ;:where 160 - ;:group-by 170 - ;:having 180 - ;:order-by 190 - ;:limit 200 - ;:offset 210 - ;:lock 215 - ;:values 220 - :query-values 230}) -;; :on-conflict -- https://www.postgresqltutorial.com/postgresql-upsert/ -;; :on-constraint (part of :on-conflict) -;; :do-update-set -;; ;do-nothing - ;:returning - (defn format-dsl [x & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] From febcf385ee69ccb4e23cc035aecb2349e19e6738 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 18:37:28 -0700 Subject: [PATCH 060/254] Yet another where helper fix Support nil conditions --- src/honey/sql/helpers.cljc | 21 +++++++++++++-------- 1 file changed, 13 insertions(+), 8 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 31c06f2..fd6c4b4 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -10,14 +10,19 @@ (defn- and-merge [current args] - (cond (= :and (first current)) - (default-merge current args) - (seq current) - (default-merge [:and current] args) - (= 1 (count args)) - (vec (first args)) - :else - (default-merge [:and] args))) + (let [args (remove nil? args)] + (cond (= :and (first current)) + (default-merge current args) + (seq current) + (if (seq args) + (default-merge [:and current] args) + current) + (= 1 (count args)) + (vec (first args)) + (seq args) + (default-merge [:and] args) + :else + (vec current)))) (def ^:private special-merges {:where #'and-merge From d1e4e196d01a01c8135c5de8e0cf1fd57d1b4944 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 18:37:48 -0700 Subject: [PATCH 061/254] Support empty conditions Which remove the clause --- src/honey/sql.cljc | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 80b0691..9cb2be0 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -263,8 +263,10 @@ params))) (defn- format-on-expr [k e] - (let [[sql & params] (format-expr e)] - (into [(str (sql-kw k) " " sql)] params))) + (if (seq e) + (let [[sql & params] (format-expr e)] + (into [(str (sql-kw k) " " sql)] params)) + [])) (defn- format-group-by [k xs] (let [[sqls params] (format-expr-list xs)] From eff3b03a81f9a824e66fdf26d0eafca6278eedb2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 18:38:05 -0700 Subject: [PATCH 062/254] Support case/when/then/else --- src/honey/sql.cljc | 17 +++++++++++++++++ 1 file changed, 17 insertions(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 9cb2be0..23623ff 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -483,6 +483,23 @@ (into params-x) (into params-a) (into params-b)))) + :case + (fn [_ clauses] + (let [[sqls params] + (reduce (fn [[sqls params] [condition value]] + (let [[sqlc & paramsc] (when-not (= :else condition) + (format-expr condition)) + [sqlv & paramsv] (format-expr value)] + [(if (= :else condition) + (conj sqls (sql-kw :else) sqlv) + (conj sqls (sql-kw :when) sqlc (sql-kw :then) sqlv)) + (-> params (into paramsc) (into paramsv))])) + [[] []] + (partition 2 clauses))] + (into [(str (sql-kw :case) " " + (str/join " " sqls) + " " (sql-kw :end))] + params))) :cast (fn [_ [x type]] (let [[sql & params] (format-expr x) From 0206eabc1ec95ee8389211a27bd4c690b58cf93a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 18:38:35 -0700 Subject: [PATCH 063/254] Empty SQL vector support Drop clauses that generate no SQL --- src/honey/sql.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 23623ff..97dea4c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -432,7 +432,7 @@ (str/join ", " (keys leftover))) leftover)) [(str "")]) - (into [(cond-> (str/join (if pretty? "\n" " ") sqls) + (into [(cond-> (str/join (if pretty? "\n" " ") (filter seq sqls)) pretty? (as-> s (str "\n" s "\n")) (and nested? (not aliased?)) From f14b73e592e750d5ee9ca3642557404f07f0ffac Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 18:50:07 -0700 Subject: [PATCH 064/254] Start merging old core tests (for helpers) --- src/honey/sql.cljc | 2 +- test/honey/sql/helpers_test.cljc | 256 ++++++++++++++++++++++++++++++- 2 files changed, 255 insertions(+), 3 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 97dea4c..ad2de6b 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -263,7 +263,7 @@ params))) (defn- format-on-expr [k e] - (if (seq e) + (if (or (not (sequential? e)) (seq e)) (let [[sql & params] (format-expr e)] (into [(str (sql-kw k) " " sql)] params)) [])) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 2c37b4a..93dd9d8 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -1,6 +1,258 @@ -;; copyright (c) sean corfield, all rights reserved +;; copyright (c) 2020 sean corfield, all rights reserved (ns honey.sql.helpers-test + (:refer-clojure :exclude [update set group-by for]) (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) - [honey.sql.helpers :as sut])) + [honey.sql :as sql] + [honey.sql.helpers :refer :all])) + +(deftest test-select + (let [m1 (-> (with [:cte (-> (select :*) + (from :example) + (where [:= :example-column 0]))]) + (select-distinct :f.* :b.baz :c.quux [:b.bla :bla-bla] + :%now [:raw "@x := 10"]) + (from [:foo :f] [:baz :b]) + (join :draq [:= :f.b :draq.x]) + (left-join [:clod :c] [:= :f.a :c.d]) + (right-join :bock [:= :bock.z :c.e]) + (full-join :beck [:= :beck.x :c.y]) + (where [:or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:< 1 2 3] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]]) + (group-by :f.a) + (having [:< 0 :f.e]) + (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) + (limit 50) + (offset 10)) + m2 {:with [[:cte {:select [:*] + :from [:example] + :where [:= :example-column 0]}]] + :select [:f.* :b.baz :c.quux [:b.bla :bla-bla] + :%now [:raw "@x := 10"]] + ;;:un-select :c.quux + :modifiers :distinct + :from [[:foo :f] [:baz :b]] + :join [:draq [:= :f.b :draq.x]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :right-join [:bock [:= :bock.z :c.e]] + :full-join [:beck [:= :beck.x :c.y]] + :where [:or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:< 1 2 3] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]] + :group-by :f.a + :having [:< 0 :f.e] + :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] + :limit 50 + :offset 10}] + (testing "Various construction methods are consistent" + (is (= m1 m2))) + (testing "SQL data formats correctly" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? " + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) + #?(:clj (testing "SQL data prints and reads correctly" + (is (= m1 (read-string (pr-str m1)))))) + #_(testing "SQL data formats correctly with alternate param naming" + (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) + ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2 AND b.baz <> $3) OR ($4 < $5 AND $6 < $7) OR (f.e in ($8, $9, $10)) OR f.e BETWEEN $11 AND $12) GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT $14 OFFSET $15 " + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) + (testing "Locking" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? FOR UPDATE " + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format (assoc m1 :lock [:for-update]) + {:params {:param1 "gabba" :param2 2} + ;; to enable :lock + :dialect :mysql})))))) + +(deftest test-cast + (is (= ["SELECT foo, CAST(bar AS integer)"] + (sql/format {:select [:foo [[:cast :bar :integer]]]}))) + (is (= ["SELECT foo, CAST(bar AS integer)"] + (sql/format {:select [:foo [[:cast :bar 'integer]]]})))) + +(deftest test-value + (is (= ["INSERT INTO foo (bar) VALUES (?)" {:baz "my-val"}] + (-> + (insert-into :foo) + (columns :bar) + (values [[:lift {:baz "my-val"}]]) + sql/format))) + (is (= ["INSERT INTO foo (a, b, c) VALUES (?, ?, ?), (?, ?, ?)" + "a" "b" "c" "a" "b" "c"] + (-> (insert-into :foo) + (values [(array-map :a "a" :b "b" :c "c") + (hash-map :a "a" :b "b" :c "c")]) + sql/format)))) + +(deftest test-operators + (testing "=" + (testing "with nil" + (is (= ["SELECT * FROM customers WHERE name IS NULL"] + (sql/format {:select [:*] + :from [:customers] + :where [:= :name nil]}))) + (is (= ["SELECT * FROM customers WHERE name = ?" nil] + (sql/format {:select [:*] + :from [:customers] + :where [:= :name :?name]} + {:name nil}))))) + (testing "in" + (doseq [[cname coll] [[:vector []] [:set #{}] [:list '()]]] + (testing (str "with values from a " (name cname)) + (let [values (conj coll 1)] + (is (= ["SELECT * FROM customers WHERE id IN (?)" 1] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE id IN (?)" 1] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}})))))) + (testing "with more than one integer" + (let [values [1 2]] + (is (= ["SELECT * FROM customers WHERE id IN (?, ?)" 1 2] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE id IN (?, ?)" 1 2] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}}))))) + (testing "with more than one string" + (let [values ["1" "2"]] + (is (= ["SELECT * FROM customers WHERE id IN (?, ?)" "1" "2"] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}) + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}}))))))) + +(deftest test-case + (is (= ["SELECT CASE WHEN foo < ? THEN ? WHEN (foo > ?) AND ((foo MOD ?) = ?) THEN foo / ? ELSE ? END FROM bar" + 0 -1 0 2 0 2 0] + (sql/format + {:select [[[:case + [:< :foo 0] -1 + [:and [:> :foo 0] [:= [:mod :foo 2] 0]] [:/ :foo 2] + :else 0]]] + :from [:bar]}))) + (let [param1 1 + param2 2 + param3 "three"] + (is (= ["SELECT CASE WHEN foo = ? THEN ? WHEN foo = bar THEN ? WHEN bar = ? THEN bar * ? ELSE ? END FROM baz" + param1 0 param2 0 param3 "param4"] + (sql/format + {:select [[[:case + [:= :foo :?param1] 0 + [:= :foo :bar] [:param :param2] + [:= :bar 0] [:* :bar :?param3] + :else "param4"]]] + :from [:baz]} + {:params + {:param1 param1 + :param2 param2 + :param3 param3}}))))) + +(deftest test-raw + (is (= ["SELECT 1 + 1 FROM foo"] + (-> (select [:raw "1 + 1"]) + (from :foo) + sql/format)))) + +(deftest test-call + (is (= ["SELECT MIN(?) FROM ?" "time" "table"] + (-> (select [[:min "time"]]) + (from "table") + sql/format)))) + +(deftest join-test + (testing "nil join" + (is (= ["SELECT * FROM foo INNER JOIN x ON foo.id = x.id INNER JOIN y"] + (-> (select :*) + (from :foo) + (join :x [:= :foo.id :x.id] :y nil) + sql/format))))) + +(deftest join-using-test + (testing "nil join" + (is (= ["SELECT * FROM foo INNER JOIN x USING (id) INNER JOIN y USING (foo, bar)"] + (-> (select :*) + (from :foo) + (join :x [:using :id] :y [:using :foo :bar]) + sql/format))))) + +(deftest inline-test + (is (= ["SELECT * FROM foo WHERE id = 5"] + (-> (select :*) + (from :foo) + (where [:= :id [:inline 5]]) + sql/format))) + ;; testing for = NULL always fails in SQL -- this test is just to show + ;; that an #inline nil should render as NULL (so make sure you only use + ;; it in contexts where a literal NULL is acceptable!) + (is (= ["SELECT * FROM foo WHERE id = NULL"] + (-> (select :*) + (from :foo) + (where [:= :id [:inline nil]]) + sql/format)))) + +(deftest where-no-params-test + (testing "where called with just the map as parameter - see #228" + (let [sqlmap (-> (select :*) + (from :table) + (where [:= :foo :bar]))] + (is (= ["SELECT * FROM table WHERE foo = bar"] + (sql/format (apply merge sqlmap []))))))) + +(deftest where-test + (is (= ["SELECT * FROM table WHERE (foo = bar) AND (quuz = xyzzy)"] + (-> (select :*) + (from :table) + (where [:= :foo :bar] [:= :quuz :xyzzy]) + sql/format))) + (is (= ["SELECT * FROM table WHERE (foo = bar) AND (quuz = xyzzy)"] + (-> (select :*) + (from :table) + (where [:= :foo :bar]) + (where [:= :quuz :xyzzy]) + sql/format)))) + +(deftest where-nil-params-test + (testing "where called with nil parameters - see #246" + (is (= ["SELECT * FROM table WHERE (foo = bar) AND (quuz = xyzzy)"] + (-> (select :*) + (from :table) + (where nil [:= :foo :bar] nil [:= :quuz :xyzzy] nil) + sql/format))) + (is (= ["SELECT * FROM table"] + (-> (select :*) + (from :table) + (where) + sql/format))) + (is (= ["SELECT * FROM table"] + (-> (select :*) + (from :table) + (where nil nil nil nil) + sql/format))))) + +(deftest cross-join-test + (is (= ["SELECT * FROM foo CROSS JOIN bar"] + (-> (select :*) + (from :foo) + (cross-join :bar) + sql/format))) + (is (= ["SELECT * FROM foo AS f CROSS JOIN bar b"] + (-> (select :*) + (from [:foo :f]) + (cross-join [:bar :b]) + sql/format)))) From b547a94003d3da11e4db935c2f446d76f1f5742d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 22:54:46 -0700 Subject: [PATCH 065/254] Restore - -> _ translation from 1.0 --- src/honey/sql.cljc | 22 ++++++++++++---------- 1 file changed, 12 insertions(+), 10 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index ad2de6b..95eb861 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -85,16 +85,18 @@ (defn sql-kw [k] (-> k (name) (upper-case) (str/replace "-" " "))) +(defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) +(defn- name-_ [x] (str/replace (name x) "-" "_")) + (defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] - (let [q (if (or *quoted* (string? x)) - (:quote *dialect*) - identity) + (let [nn (if (or *quoted* (string? x)) name name-_) + q (if (or *quoted* (string? x)) (:quote *dialect*) identity) [t c] (if-let [n (when-not (or drop-ns? (string? x)) - (namespace x))] - [n (name x)] + (namespace-_ x))] + [n (nn x)] (if aliased? - [nil (name x)] - (let [[t c] (str/split (name x) #"\.")] + [nil (nn x)] + (let [[t c] (str/split (nn x) #"\.")] (if c [t c] [nil t]))))] (cond->> c (not= "*" c) @@ -113,7 +115,7 @@ {:params (keys params)})))))})) (defn- format-var [x & [opts]] - (let [c (name x)] + (let [c (name-_ x)] (cond (= \% (first c)) (let [[f & args] (str/split (subs c 1) #"\.")] ;; TODO: this does not quote arguments -- does that matter? @@ -464,8 +466,8 @@ (cond (nil? x) "NULL" (string? x) (str \' (str/replace x "'" "''") \') - (symbol? x) (name x) - (keyword? x) (name x) + (symbol? x) (name-_ x) + (keyword? x) (name-_ x) :else (str x))) (def ^:private special-syntax From 8025d3520d6cdb66a76ce73d9aa7fad78158d927 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 22:54:59 -0700 Subject: [PATCH 066/254] Bug fixes for JOINs --- src/honey/sql.cljc | 20 +++++++++++++------- 1 file changed, 13 insertions(+), 7 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 95eb861..0e7c875 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -256,13 +256,19 @@ [(str (sql-kw k) " " (format-entity-alias table))]) [(str (sql-kw k) " " (format-entity-alias table))])) -(defn- format-join [k [j e]] - (let [[sql & params] (format-expr e)] - ;; for backward compatibility, treat plain JOIN as INNER JOIN: - (into [(str (sql-kw (if (= :join k) :inner-join k)) " " - (format-entity-alias j) " ON " - sql)] - params))) +(defn- format-join [k clauses] + (let [[sqls params] + (reduce (fn [[sqls params] [j e]] + ;; TODO: join using! + (let [[sql & params'] (when e (format-expr e))] + [(cond-> (conj sqls + (sql-kw (if (= :join k) :inner-join k)) + (format-entity-alias j)) + e (conj "ON" sql)) + (into params params')])) + [[] []] + (partition 2 clauses))] + (into [(str/join " " sqls)] params))) (defn- format-on-expr [k e] (if (or (not (sequential? e)) (seq e)) From 9da9dfe399a2347254b194bc335f9c1f74e8afaa Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 22:55:16 -0700 Subject: [PATCH 067/254] Fix test for issue 263 --- test/honey/sql_test.cljc | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 431be52..3e351ce 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -72,11 +72,11 @@ ;; issue-based tests (deftest subquery-alias-263 - (is (= ["SELECT type FROM (SELECT address AS field-alias FROM Candidate) AS sub-q-alias"] + (is (= ["SELECT type FROM (SELECT address AS field_alias FROM Candidate) AS sub_q_alias"] (sut/format {:select [:type] :from [[{:select [[:address :field-alias]] - :from [:Candidate]} :sub-q-alias]]}))) - (is (= ["SELECT type FROM (SELECT address field-alias FROM Candidate) sub-q-alias"] + :from [:Candidate]} :sub_q_alias]]}))) + (is (= ["SELECT type FROM (SELECT address field_alias FROM Candidate) sub_q_alias"] (sut/format {:select [:type] :from [[{:select [[:address :field-alias]] :from [:Candidate]} :sub-q-alias]]} From b71104454831ae0cc6b846ce7dcb16b3a98aff9d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Oct 2020 22:56:47 -0700 Subject: [PATCH 068/254] Minor syntax differences `:group-by` must take sequence. `:<` is binary only. `:select-distinct` instead of modifier. --- test/honey/sql/helpers_test.cljc | 30 ++++++++++++++---------------- 1 file changed, 14 insertions(+), 16 deletions(-) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 93dd9d8..945d3c0 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -11,8 +11,8 @@ (let [m1 (-> (with [:cte (-> (select :*) (from :example) (where [:= :example-column 0]))]) - (select-distinct :f.* :b.baz :c.quux [:b.bla :bla-bla] - :%now [:raw "@x := 10"]) + (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]) (from [:foo :f] [:baz :b]) (join :draq [:= :f.b :draq.x]) (left-join [:clod :c] [:= :f.a :c.d]) @@ -20,7 +20,7 @@ (full-join :beck [:= :beck.x :c.y]) (where [:or [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:< 1 2 3] + [:and [:< 1 2] [:< 2 3]] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]]) (group-by :f.a) @@ -31,10 +31,8 @@ m2 {:with [[:cte {:select [:*] :from [:example] :where [:= :example-column 0]}]] - :select [:f.* :b.baz :c.quux [:b.bla :bla-bla] - :%now [:raw "@x := 10"]] - ;;:un-select :c.quux - :modifiers :distinct + :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]] :from [[:foo :f] [:baz :b]] :join [:draq [:= :f.b :draq.x]] :left-join [[:clod :c] [:= :f.a :c.d]] @@ -42,10 +40,10 @@ :full-join [:beck [:= :beck.x :c.y]] :where [:or [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:< 1 2 3] + [:and [:< 1 2] [:< 2 3]] [:in :f.e [1 [:param :param2] 3]] [:between :f.e 10 20]] - :group-by :f.a + :group-by [:f.a] :having [:< 0 :f.e] :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] :limit 50 @@ -53,22 +51,22 @@ (testing "Various construction methods are consistent" (is (= m1 m2))) (testing "SQL data formats correctly" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? " + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) #?(:clj (testing "SQL data prints and reads correctly" (is (= m1 (read-string (pr-str m1)))))) #_(testing "SQL data formats correctly with alternate param naming" (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) - ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2 AND b.baz <> $3) OR ($4 < $5 AND $6 < $7) OR (f.e in ($8, $9, $10)) OR f.e BETWEEN $11 AND $12) GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT $14 OFFSET $15 " + ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) (testing "Locking" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? FOR UPDATE " + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla `bla-bla`, now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format (assoc m1 :lock [:for-update]) + (sql/format (assoc m1 :lock [:in-share-mode]) {:params {:param1 "gabba" :param2 2} ;; to enable :lock - :dialect :mysql})))))) + :dialect :mysql :quoted false})))))) (deftest test-cast (is (= ["SELECT foo, CAST(bar AS integer)"] @@ -101,7 +99,7 @@ (sql/format {:select [:*] :from [:customers] :where [:= :name :?name]} - {:name nil}))))) + {:params {:name nil}}))))) (testing "in" (doseq [[cname coll] [[:vector []] [:set #{}] [:list '()]]] (testing (str "with values from a " (name cname)) @@ -165,7 +163,7 @@ (deftest test-raw (is (= ["SELECT 1 + 1 FROM foo"] - (-> (select [:raw "1 + 1"]) + (-> (select [[:raw "1 + 1"]]) (from :foo) sql/format)))) From 4dcc44d878d53be42470905f78da01f2ddec74a2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 14 Oct 2020 11:00:20 -0700 Subject: [PATCH 069/254] Fix - as operator Not a great workaround. May rethink depending on what other operators get added containing `-`. --- src/honey/sql.cljc | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0e7c875..2df57d9 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -83,7 +83,8 @@ :cljs str/upper-case)) (defn sql-kw [k] - (-> k (name) (upper-case) (str/replace "-" " "))) + (-> k (name) (upper-case) + (as-> s (if (= "-" s) s (str/replace s "-" " "))))) (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) From b762a514b648271264fc0a4be560b372c573efec Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 14 Oct 2020 11:00:39 -0700 Subject: [PATCH 070/254] Addresses #280 by adding similar to / not similar to --- src/honey/sql.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 2df57d9..30e7d20 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -458,7 +458,7 @@ (def ^:private infix-ops (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "in" "not-in" "like" "not-like" "regexp" - "ilike" "not-ilike" + "ilike" "not-ilike" "similar-to" "not-similar-to" "is" "is-not" "not=" "!=" "regex"} (into (map str "+-*/%|&^=<>")) (into (keys infix-aliases)) From 273732089b548f3fbe2fd26cdd00fdab3c4bfa29 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 14 Oct 2020 11:50:32 -0700 Subject: [PATCH 071/254] Improve :inline/:raw Note: these are still in flux! --- src/honey/sql.cljc | 13 ++++++++----- test/honey/sql_test.cljc | 2 +- 2 files changed, 9 insertions(+), 6 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 30e7d20..3b15072 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -473,8 +473,8 @@ (cond (nil? x) "NULL" (string? x) (str \' (str/replace x "'" "''") \') - (symbol? x) (name-_ x) - (keyword? x) (name-_ x) + (symbol? x) (sql-kw x) + (keyword? x) (sql-kw x) :else (str x))) (def ^:private special-syntax @@ -525,7 +525,9 @@ ["DEFAULT"]) :inline (fn [_ [x]] - [(sqlize-value x)]) + (if (sequential? x) + [(str/join " " (map #'sqlize-value x))] + [(sqlize-value x)])) :interval (fn [_ [n units]] (let [[sql & params] (format-expr n)] @@ -544,9 +546,10 @@ (fn [_ [k]] ["?" (->param k)]) :raw - ;; TODO: only supports single raw string right now (fn [_ [s]] - [s])})) + (if (sequential? s) + [(str/join " " s)] + [s]))})) (defn format-expr [x & [{:keys [nested?] :as opts}]] (cond (or (keyword? x) (symbol? x)) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3e351ce..40e04f1 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -359,7 +359,7 @@ (format {:dialect :mysql}))))) (deftest inlined-values-are-stringified-correctly - (is (= ["SELECT 'foo', 'It''s a quote!', bar, NULL"] + (is (= ["SELECT 'foo', 'It''s a quote!', BAR, NULL"] (format {:select [[[:inline "foo"]] [[:inline "It's a quote!"]] [[:inline :bar]] From 39a83ae57ee7d7ade669950c2326afa6812ca632 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 28 Oct 2020 16:26:35 -0700 Subject: [PATCH 072/254] Add test to V2 for issue #282 --- test/honey/sql/helpers_test.cljc | 17 +++++++++++++++++ 1 file changed, 17 insertions(+) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 945d3c0..571e463 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -254,3 +254,20 @@ (from [:foo :f]) (cross-join [:bar :b]) sql/format)))) + +(defn- stack-overflow-282 [num-ids] + (let [ids (range num-ids)] + (sql/format (reduce + where + {:select [[:id :id]] + :from [:collection] + :where [:= :personal_owner_id nil]} + (clojure.core/for [id ids] + [:not-like :location [:raw (clojure.core/format "'/%d/%%'" id)]]))))) + +(deftest issue-282 + (is (= [(str "SELECT id AS id FROM collection" + " WHERE (personal_owner_id IS NULL)" + " AND (location NOT LIKE '/0/%')" + " AND (location NOT LIKE '/1/%')")] + (stack-overflow-282 2)))) From 117e1c7f64c7b961dc2a4c1b05d13f70530ca159 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 8 Nov 2020 21:17:39 -0800 Subject: [PATCH 073/254] Update to latest depstar --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index 93e04bc..7bb25b4 100644 --- a/deps.edn +++ b/deps.edn @@ -20,7 +20,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.128"}} + :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.133"}} :main-opts ["-m" "hf.depstar.jar" "honeysql.jar"]} :install {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} :main-opts ["-m" "deps-deploy.deps-deploy" "install" "honeysql.jar"]} From 17c5e4b980e1f80328bd5dc4fc7bbda44366aa1a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 4 Dec 2020 10:28:09 -0800 Subject: [PATCH 074/254] Add test for question in #285 --- .gitignore | 1 + test/honey/sql_test.cljc | 16 +++++++++++++++- 2 files changed, 16 insertions(+), 1 deletion(-) diff --git a/.gitignore b/.gitignore index 64d7077..65353aa 100644 --- a/.gitignore +++ b/.gitignore @@ -12,6 +12,7 @@ .clj-kondo/.cache .eastwood .nrepl-port +.socket-repl-port .classpath .project .nrepl-port diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 40e04f1..36f63ba 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -4,7 +4,8 @@ (:refer-clojure :exclude [format]) (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) - [honey.sql :as sut :refer [format]])) + [honey.sql :as sut :refer [format]] + [honey.sql.helpers :as h])) (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] @@ -525,3 +526,16 @@ DO UPDATE SET email = EXCLUDED.email || ';' || customers.email :on-conflict :name :do-update-set {:email [:|| :EXCLUDED.email [:inline ";"] :customers.email]}} {:pretty? true})))) + +(deftest issue-285 + (is (= [" +SELECT * +FROM processes +WHERE state = ? +ORDER BY id = ? DESC +" 42 123] + (format (-> (h/select :*) + (h/from :processes) + (h/where [:= :state 42]) + (h/order-by [[:= :id 123] :desc])) + {:pretty? true})))) From 57dbfaad482f89cc7f11e9de5c8839b583414804 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 15 Dec 2020 10:12:39 -0800 Subject: [PATCH 075/254] Add example from PR #287 to v2 README --- README.md | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/README.md b/README.md index 9d6d7fb..e89b4cc 100644 --- a/README.md +++ b/README.md @@ -56,6 +56,13 @@ to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jd (jdbc/execute! conn (sql/format sqlmap)) ``` +If you want to format the query as a string with no parameters (e.g. to use the SQL statement in a SQL console), pass `:inline true` as an option to `sql/format`: + +```clj +(sql/format sqlmap {:inline true}) +=> ["SELECT a, b, c FROM foo WHERE f.a = 'baz'"] +``` + > Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you. _The handling of namespace-qualified keywords is under review in 2.x._ From ef8fd666896c9df9ce74cf8f784e4b42fbc6e265 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 15 Dec 2020 10:27:06 -0800 Subject: [PATCH 076/254] Add FUNDING.yml --- .github/FUNDING.yml | 1 + 1 file changed, 1 insertion(+) create mode 100644 .github/FUNDING.yml diff --git a/.github/FUNDING.yml b/.github/FUNDING.yml new file mode 100644 index 0000000..3b380ac --- /dev/null +++ b/.github/FUNDING.yml @@ -0,0 +1 @@ +github: seancorfield From 8b70ebd83f526f646bafe436c61a16154d9254f2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 15 Dec 2020 10:34:26 -0800 Subject: [PATCH 077/254] Update Clojure CLI versions --- .github/workflows/test.yml | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index bded007..44ec488 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -15,8 +15,8 @@ jobs: with: java-version: ${{ matrix.java }} - name: Setup Clojure - uses: DeLaGuardo/setup-clojure@2.0 + uses: DeLaGuardo/setup-clojure@master with: - tools-deps: '1.10.1.708' + tools-deps: '1.10.1.754' - name: Run Tests run: sh run-tests.sh all From 0880d0212f8dfefd791a16d0114df5534f264ad0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 29 Jan 2021 13:17:01 -0800 Subject: [PATCH 078/254] Minor version/tooling updates --- README.md | 3 ++- deps.edn | 19 +++++++++++-------- 2 files changed, 13 insertions(+), 9 deletions(-) diff --git a/README.md b/README.md index e89b4cc..54c3679 100644 --- a/README.md +++ b/README.md @@ -344,7 +344,7 @@ to identify inline parameter values, and how to add in raw SQL fragments! ``` ```clojure call-qualify-map -=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] +=> {:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ``` @@ -607,6 +607,7 @@ or `clojure.java.jdbc`'s [`ISQLValue`](https://clojure.github.io/java.jdbc/#cloj _This bit no longer exists:_ To teach HoneySQL how to handle your datatype you need to implement [`honeysql.format/ToSql`](https://github.com/seancorfield/honeysql/blob/a9dffec632be62c961be7d9e695d0b2b85732c53/src/honeysql/format.cljc#L94). For example: + ``` clojure ;; given: (defrecord MyDateWrapper [...] diff --git a/deps.edn b/deps.edn index 7bb25b4..be2cf39 100644 --- a/deps.edn +++ b/deps.edn @@ -1,11 +1,11 @@ {:mvn/repos {"sonatype" {:url "https://oss.sonatype.org/content/repositories/snapshots/"}} :paths ["src" "resources"] - :deps {org.clojure/clojure {:mvn/version "1.10.1"}} + :deps {org.clojure/clojure {:mvn/version "1.10.2"}} :aliases {:1.7 {:override-deps {org.clojure/clojure {:mvn/version "1.7.0"}}} :1.8 {:override-deps {org.clojure/clojure {:mvn/version "1.8.0"}}} :1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} - :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.1"}}} + :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.2"}}} :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.0-master-SNAPSHOT"}}} :test {:extra-paths ["test"]} :runner @@ -13,6 +13,7 @@ {:git/url "https://github.com/cognitect-labs/test-runner" :sha "b6b3193fcc42659d7e46ecd1884a228993441182"}} :main-opts ["-m" "cognitect.test-runner" + ;"-d" "target/test-doc-blocks/test" "-d" "test"]} :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.7.0"}} :main-opts ["-m" "cljs-test-runner.main"]} @@ -20,9 +21,11 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:extra-deps {seancorfield/depstar {:mvn/version "1.1.133"}} - :main-opts ["-m" "hf.depstar.jar" "honeysql.jar"]} - :install {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} - :main-opts ["-m" "deps-deploy.deps-deploy" "install" "honeysql.jar"]} - :deploy {:extra-deps {slipset/deps-deploy {:mvn/version "0.1.1"}} - :main-opts ["-m" "deps-deploy.deps-deploy" "deploy" "honeysql.jar"]}}} + :jar {:replace-deps {seancorfield/depstar {:mvn/version "2.0.171"}} + :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar"}} + :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} + :exec-fn deps-deploy.deps-deploy/deploy + :exec-args {:installer :local :artifact "honeysql.jar"}} + :deploy {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} + :exec-fn deps-deploy.deps-deploy/deploy + :exec-args {:installer :remote :artifact "honeysql.jar"}}}} From 86a4d2056b8987d4faf0036de6f771ee5ad6ff76 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 29 Jan 2021 14:56:06 -0800 Subject: [PATCH 079/254] Auto-sync pom.cml --- deps.edn | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index be2cf39..1b37090 100644 --- a/deps.edn +++ b/deps.edn @@ -22,7 +22,8 @@ :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} :jar {:replace-deps {seancorfield/depstar {:mvn/version "2.0.171"}} - :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar"}} + :exec-fn hf.depstar/jar + :exec-args {:jar "honeysql.jar" :sync-pom true}} :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} :exec-fn deps-deploy.deps-deploy/deploy :exec-args {:installer :local :artifact "honeysql.jar"}} From 87eec786e14f1f2e169481e1cf1583f520d1654c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 29 Jan 2021 16:11:52 -0800 Subject: [PATCH 080/254] It's 2021 --- README.md | 2 +- src/honey/specs.clj | 2 +- src/honey/sql.cljc | 2 +- src/honey/sql/helpers.cljc | 2 +- test/honey/sql/helpers_test.cljc | 2 +- 5 files changed, 5 insertions(+), 5 deletions(-) diff --git a/README.md b/README.md index 54c3679..855fb04 100644 --- a/README.md +++ b/README.md @@ -637,6 +637,6 @@ To teach HoneySQL how to handle your datatype you need to implement [`honeysql.f ## License -Copyright (c) 2020 Sean Corfield. HoneySQL 1.x was copyright (c) 2012-2020 Justin Kramer and Sean Corfield. +Copyright (c) 2020-2021 Sean Corfield. HoneySQL 1.x was copyright (c) 2012-2020 Justin Kramer and Sean Corfield. Distributed under the Eclipse Public License, the same as Clojure. diff --git a/src/honey/specs.clj b/src/honey/specs.clj index cb2d631..39042bd 100644 --- a/src/honey/specs.clj +++ b/src/honey/specs.clj @@ -1,4 +1,4 @@ -;; copyright (c) 2020 sean corfield, all rights reserved +;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.specs "Optional namespace containing `clojure.spec` representations of diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3b15072..39e25d8 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -1,4 +1,4 @@ -;; copyright (c) 2020 sean corfield, all rights reserved +;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql "Primary API for HoneySQL 2.x." diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index fd6c4b4..f0ea26c 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -1,4 +1,4 @@ -;; copyright (c) 2020 sean corfield, all rights reserved +;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 571e463..540ac86 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -1,4 +1,4 @@ -;; copyright (c) 2020 sean corfield, all rights reserved +;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql.helpers-test (:refer-clojure :exclude [update set group-by for]) From 830301c843abcfdb8363fe6e3815a46ea749e4ca Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 16:40:01 -0800 Subject: [PATCH 081/254] Ignore Rebel Readline/Socket history files --- .gitignore | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.gitignore b/.gitignore index 65353aa..409bedf 100644 --- a/.gitignore +++ b/.gitignore @@ -12,9 +12,9 @@ .clj-kondo/.cache .eastwood .nrepl-port -.socket-repl-port +/.rebel_readline_history +/.socket-repl-port .classpath .project -.nrepl-port bin /cljs-test-runner-out From 07eb66759a43e92ba539c6bd450c474b8d49dcd2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 17:27:00 -0800 Subject: [PATCH 082/254] Restore cljs compatibility --- README.md | 2 +- src/honey/sql.cljc | 3 ++- test/honey/sql/helpers_test.cljc | 7 +++++-- 3 files changed, 8 insertions(+), 4 deletions(-) diff --git a/README.md b/README.md index 855fb04..eae23aa 100644 --- a/README.md +++ b/README.md @@ -344,7 +344,7 @@ to identify inline parameter values, and how to add in raw SQL fragments! ``` ```clojure call-qualify-map -=> {:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] +=> '{:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]] :from (:foo) :select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]} ``` diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 39e25d8..3ad5f5b 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -460,10 +460,11 @@ "in" "not-in" "like" "not-like" "regexp" "ilike" "not-ilike" "similar-to" "not-similar-to" "is" "is-not" "not=" "!=" "regex"} - (into (map str "+-*/%|&^=<>")) + (into (map str "+-*%|&^=<>")) (into (keys infix-aliases)) (into (vals infix-aliases)) (->> (into #{} (map keyword))) + (conj :/) ; because (keyword "/") does not work in cljs (atom))) (def ^:private op-ignore-nil (atom #{:and :or})) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 540ac86..034b716 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -5,7 +5,10 @@ (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] - [honey.sql.helpers :refer :all])) + [honey.sql.helpers + :refer [columns cross-join from full-join group-by having insert-into + join left-join limit offset order-by right-join + select select-distinct values where with]])) (deftest test-select (let [m1 (-> (with [:cte (-> (select :*) @@ -263,7 +266,7 @@ :from [:collection] :where [:= :personal_owner_id nil]} (clojure.core/for [id ids] - [:not-like :location [:raw (clojure.core/format "'/%d/%%'" id)]]))))) + [:not-like :location [:raw (str "'/" id "/%'")]]))))) (deftest issue-282 (is (= [(str "SELECT id AS id FROM collection" From d0f3068f3fcd547381a0d862fd55f9bed2dc5b9d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:00:22 -0800 Subject: [PATCH 083/254] Minor README update around raw --- README.md | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/README.md b/README.md index eae23aa..7f05325 100644 --- a/README.md +++ b/README.md @@ -381,14 +381,13 @@ will not be lifted out as parameters, so they end up in the SQL string as-is. Raw SQL can also be supplied as a vector of strings and values. Strings are rendered as-is into the formatted SQL string. Non-strings are lifted as -parameters. If you need a string parameter lifted, you must use `:param` -or the `param` helper. +parameters. If you need a string parameter lifted, you must use `:param`. ```clojure (-> (select :*) (from :foo) (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) - (sql/format {:foo 5})) + (sql/format)) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ``` From d5b11e2da633865dd7843be3a620417696506e4e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:00:34 -0800 Subject: [PATCH 084/254] Implement JOIN USING --- src/honey/sql.cljc | 18 ++++++++++++------ 1 file changed, 12 insertions(+), 6 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3ad5f5b..d9a52a2 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -260,13 +260,19 @@ (defn- format-join [k clauses] (let [[sqls params] (reduce (fn [[sqls params] [j e]] - ;; TODO: join using! - (let [[sql & params'] (when e (format-expr e))] - [(cond-> (conj sqls + (let [sqls (conj sqls (sql-kw (if (= :join k) :inner-join k)) - (format-entity-alias j)) - e (conj "ON" sql)) - (into params params')])) + (format-entity-alias j))] + (if (and (sequential? e) (= :using (first e))) + [(conj sqls + "USING" + (str "(" + (str/join ", " (map #'format-entity-alias (rest e))) + ")")) + params] + (let [[sql & params'] (when e (format-expr e))] + [(cond-> sqls e (conj "ON" sql)) + (into params params')])))) [[] []] (partition 2 clauses))] (into [(str/join " " sqls)] params))) From d2968bbfcc8f2eed2e49982b5a4fb43183505ed3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:19:12 -0800 Subject: [PATCH 085/254] Fixes #289 by implementing USING --- src/honey/sql.cljc | 3 ++- src/honey/sql/helpers.cljc | 1 + test/honey/sql_test.cljc | 9 +++++++++ 3 files changed, 12 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index d9a52a2..0971799 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -18,7 +18,7 @@ "The (default) order for known clauses. Can have items added and removed." [:nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :insert-into :update :delete :delete-from :truncate - :columns :set :from + :columns :set :from :using :join :left-join :right-join :inner-join :outer-join :full-join :cross-join :where :group-by :having :order-by :limit :offset :for :values @@ -401,6 +401,7 @@ :columns #'format-columns :set #'format-set-exprs :from #'format-selects + :using #'format-selects :join #'format-join :left-join #'format-join :right-join #'format-join diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index f0ea26c..bb429a1 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -61,6 +61,7 @@ (defn columns [& args] (generic :columns args)) (defn set [& args] (generic-1 :set args)) (defn from [& args] (generic :from args)) +(defn using [& args] (generic :using args)) (defn join [& args] (generic :join args)) (defn left-join [& args] (generic :left-join args)) (defn right-join [& args] (generic :right-join args)) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 36f63ba..de5706d 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -354,6 +354,15 @@ :where [:= :t1.bar 42]} (format {:dialect :mysql}))))) +(deftest delete-using + (is (= ["DELETE FROM films USING producers WHERE (producer_id = producers.id) AND (producers.name = ?)" "foo"] + (-> {:delete-from :films + :using [:producers] + :where [:and + [:= :producer_id :producers.id] + [:= :producers.name "foo"]]} + (format))))) + (deftest truncate-test (is (= ["TRUNCATE `foo`"] (-> {:truncate :foo} From 8373c72f45170ef7f3d4cc4fe59399fc2cdf08be Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:43:48 -0800 Subject: [PATCH 086/254] Fixes #286 by supporting WAIT, SKIP LOCKED NOWAIT was already supported. --- src/honey/sql.cljc | 6 +++--- test/honey/sql_test.cljc | 8 ++++++++ 2 files changed, 11 insertions(+), 3 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0971799..07657a4 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -301,15 +301,15 @@ [(str (sql-kw k) " " (sql-kw strength) (when tables (str - (cond (= :nowait tables) - (str " NOWAIT") + (cond (#{:nowait :skip-locked :wait} tables) + (str " " (sql-kw tables)) (sequential? tables) (str " OF " (str/join ", " (map #'format-entity tables))) :else (str " OF " (format-entity tables))) (when nowait - (str " NOWAIT")))))])) + (str " " (sql-kw nowait))))))])) (defn- format-values [k xs] (cond (sequential? (first xs)) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index de5706d..9af6179 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -432,6 +432,14 @@ (format {:select [:*] :from :foo :for [:update :nowait]}))) (is (= ["SELECT * FROM foo FOR UPDATE OF bar NOWAIT"] (format {:select [:*] :from :foo :for [:update :bar :nowait]}))) + (is (= ["SELECT * FROM foo FOR UPDATE WAIT"] + (format {:select [:*] :from :foo :for [:update :wait]}))) + (is (= ["SELECT * FROM foo FOR UPDATE OF bar WAIT"] + (format {:select [:*] :from :foo :for [:update :bar :wait]}))) + (is (= ["SELECT * FROM foo FOR UPDATE SKIP LOCKED"] + (format {:select [:*] :from :foo :for [:update :skip-locked]}))) + (is (= ["SELECT * FROM foo FOR UPDATE OF bar SKIP LOCKED"] + (format {:select [:*] :from :foo :for [:update :bar :skip-locked]}))) (is (= ["SELECT * FROM foo FOR UPDATE OF bar, quux"] (format {:select [:*] :from :foo :for [:update [:bar :quux]]})))) (testing "MySQL for/lock" From 67c6c3a2cf7c9d090f0b447fba1968701ccb7871 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:50:14 -0800 Subject: [PATCH 087/254] Fixes #275 by dropping 1.7 & 1.8 --- deps.edn | 4 +--- run-tests.sh | 2 +- src/honey/sql.cljc | 2 +- 3 files changed, 3 insertions(+), 5 deletions(-) diff --git a/deps.edn b/deps.edn index 1b37090..b9eef19 100644 --- a/deps.edn +++ b/deps.edn @@ -2,9 +2,7 @@ :paths ["src" "resources"] :deps {org.clojure/clojure {:mvn/version "1.10.2"}} :aliases - {:1.7 {:override-deps {org.clojure/clojure {:mvn/version "1.7.0"}}} - :1.8 {:override-deps {org.clojure/clojure {:mvn/version "1.8.0"}}} - :1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} + {:1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.2"}}} :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.0-master-SNAPSHOT"}}} :test {:extra-paths ["test"]} diff --git a/run-tests.sh b/run-tests.sh index 9f5e209..9164ed7 100755 --- a/run-tests.sh +++ b/run-tests.sh @@ -8,7 +8,7 @@ if test $? -eq 0 then if test "$1" = "all" then - for v in 1.7 1.8 1.9 1.10 master + for v in 1.9 1.10 master do echo ==== Test Clojure $v ==== clojure -M:test:runner:$v diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 07657a4..f0a27bb 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -625,7 +625,7 @@ (let [[sqls params] (format-expr-list x)] (into [(str "(" (str/join ", " sqls) ")")] params)))) - (or (true? x) (false? x)) ; because (boolean? x) requires Clojure 1.9+ + (boolean? x) [(upper-case (str x))] (nil? x) From 0090bf4d1c8d6fce915a676d47d2bea63fd2a21e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:52:07 -0800 Subject: [PATCH 088/254] Drop 1.7 & 1.8 from CircleCI as well --- .circleci/config.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index cb4ba1c..387e56b 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -16,7 +16,7 @@ jobs: command: sudo ln -s /usr/bin/js /usr/bin/node - run: name: Download Dependencies - command: clojure -Spath -R:test:runner:cljs-runner:eastwood:readme && clojure -Spath -A:1.7 && clojure -Spath -A:1.8 && clojure -Spath -A:1.9 + command: clojure -Spath -R:test:runner:cljs-runner:eastwood:readme && clojure -Spath -A:1.9 - save_cache: paths: - ~/.m2 From 4af4f3f7ed7c052535987129384908ab22002bbb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 11:59:35 -0800 Subject: [PATCH 089/254] Fixes #274 by committing to seancorfield/honeysql for v2 --- README.md | 2 +- deps.edn | 2 +- pom.xml | 8 ++++---- 3 files changed, 6 insertions(+), 6 deletions(-) diff --git a/README.md b/README.md index 7f05325..cf25644 100644 --- a/README.md +++ b/README.md @@ -6,7 +6,7 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim The latest stable version (1.0.444) on Clojars and on cljdoc: -[![Clojars Project](https://clojars.org/honeysql/latest-version.svg)](https://clojars.org/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.444)](https://cljdoc.org/d/honeysql/honeysql/CURRENT) +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.next)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. diff --git a/deps.edn b/deps.edn index b9eef19..92506fd 100644 --- a/deps.edn +++ b/deps.edn @@ -1,5 +1,5 @@ {:mvn/repos {"sonatype" {:url "https://oss.sonatype.org/content/repositories/snapshots/"}} - :paths ["src" "resources"] + :paths ["src"] :deps {org.clojure/clojure {:mvn/version "1.10.2"}} :aliases {:1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} diff --git a/pom.xml b/pom.xml index fda7cfd..6fa4e12 100644 --- a/pom.xml +++ b/pom.xml @@ -1,9 +1,9 @@ 4.0.0 - honeysql + seancorfield honeysql - 1.0.444 + 2.0.next honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,13 +25,13 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v1.0.444 + v2.0.next org.clojure clojure - 1.10.1 + 1.10.2 From 429761f106ff485f26fc5bc44d29d911219c38df Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 12:35:51 -0800 Subject: [PATCH 090/254] Fixes #261 by re-implementing :raw --- README.md | 12 ++++++++++-- doc/differences-from-1-x.md | 3 +-- src/honey/sql.cljc | 11 ++++++++++- 3 files changed, 21 insertions(+), 5 deletions(-) diff --git a/README.md b/README.md index cf25644..9998930 100644 --- a/README.md +++ b/README.md @@ -388,17 +388,25 @@ parameters. If you need a string parameter lifted, you must use `:param`. (from :foo) (where [:< :expired_at [:raw ["now() - '" 5 " seconds'"]]]) (sql/format)) -=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] +=> ["SELECT * FROM foo WHERE expired_at < now() - '5 seconds'"] ``` ```clojure (-> (select :*) (from :foo) (where [:< :expired_at [:raw ["now() - '" [:param :t] " seconds'"]]]) - (sql/format {:t 5})) + (sql/format {:params {:t 5}})) => ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] ``` +```clojure +(-> (select :*) + (from :foo) + (where [:< :expired_at [:raw ["now() - " [:inline (str 5 " seconds")]]]]) + (sql/format)) +=> ["SELECT * FROM foo WHERE expired_at < now() - '5 seconds'"] +``` + #### Identifiers To quote identifiers, pass the `:quoted true` option to `format` and they will diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index ab94f6a..6153972 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -96,11 +96,10 @@ The following new syntax has been added: * `:array` -- used as a function to replace the `sql/array` / `#sql/array` machinery, * `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, * `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. +* `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the v1 behavior but should be more flexible. > Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). -> Note 2: expect `:raw` to be added in some form before release. - ## Extensibility The protocols and multimethods in 1.x have all gone away. The primary extension point is `honey.sql/register-clause!` which lets you specify the new clause (keyword), the formatter function for it, and the existing clause that it should be ranked before (`format` processes the DSL in clause order). diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f0a27bb..5ea1f58 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -556,7 +556,16 @@ :raw (fn [_ [s]] (if (sequential? s) - [(str/join " " s)] + (let [[sqls params] + (reduce (fn [[sqls params] s] + (if (vector? s) + (let [[sql & params'] (format-expr s)] + [(conj sqls sql) + (into params params')]) + [(conj sqls s) params])) + [[] []] + s)] + (into [(str/join sqls)] params)) [s]))})) (defn format-expr [x & [{:keys [nested?] :as opts}]] From 1f4c4ff7ba1039315d0bb1963270798ea43aa5bb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 30 Jan 2021 12:42:08 -0800 Subject: [PATCH 091/254] Show :lift example in :raw --- README.md | 8 ++++++++ 1 file changed, 8 insertions(+) diff --git a/README.md b/README.md index 9998930..873757c 100644 --- a/README.md +++ b/README.md @@ -391,6 +391,14 @@ parameters. If you need a string parameter lifted, you must use `:param`. => ["SELECT * FROM foo WHERE expired_at < now() - '5 seconds'"] ``` +```clojure +(-> (select :*) + (from :foo) + (where [:< :expired_at [:raw ["now() - '" [:lift 5] " seconds'"]]]) + (sql/format)) +=> ["SELECT * FROM foo WHERE expired_at < now() - '? seconds'" 5] +``` + ```clojure (-> (select :*) (from :foo) From c92656389b61280f36cd5cb91a0b96319d6b938d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 05:08:21 -0800 Subject: [PATCH 092/254] Make params dynamic/implement in/not-in --- src/honey/sql.cljc | 44 +++++++++++++++++++++++++++++++------------- 1 file changed, 31 insertions(+), 13 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5ea1f58..a1c275b 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -65,6 +65,7 @@ (def ^:private ^:dynamic *clause-order* default-clause-order) (def ^:private ^:dynamic *quoted* nil) (def ^:private ^:dynamic *inline* nil) +(def ^:private ^:dynamic *params* nil) ;; clause helpers @@ -108,12 +109,12 @@ (defn- ->param [k] (with-meta (constantly k) {::wrapper - (fn [fk {:keys [params]}] + (fn [fk _] (let [k (fk)] - (if (contains? params k) - (get params k) + (if (contains? *params* k) + (get *params* k) (throw (ex-info (str "missing parameter value for " k) - {:params (keys params)})))))})) + {:params (keys *params*)})))))})) (defn- format-var [x & [opts]] (let [c (name-_ x)] @@ -464,7 +465,7 @@ (def ^:private infix-ops (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" - "in" "not-in" "like" "not-like" "regexp" + "like" "not-like" "regexp" "ilike" "not-ilike" "similar-to" "not-similar-to" "is" "is-not" "not=" "!=" "regex"} (into (map str "+-*%|&^=<>")) @@ -485,6 +486,26 @@ (keyword? x) (sql-kw x) :else (str x))) +(defn- unwrap [x opts] + (if-let [m (meta x)] + (if-let [f (::wrapper m)] + (f x opts) + x) + x)) + +(defn- format-in [in [x y]] + (let [[sql-x & params-x] (format-expr x {:nested? true}) + [sql-y & params-y] (format-expr y {:nested? true}) + values (unwrap (first params-y) {})] + (if (and (= "?" sql-y) (= 1 (count params-y)) (coll? values)) + (let [sql (str "(" (str/join ", " (repeat (count values) "?")) ")")] + (-> [(str sql-x " " (sql-kw in) " " sql)] + (into params-x) + (into values))) + (-> [(str sql-x " " (sql-kw in) " " sql-y)] + (into params-x) + (into params-y))))) + (def ^:private special-syntax (atom {:array @@ -618,6 +639,9 @@ (vector) (into p1) (into p2))))) + (contains? #{:in :not-in} op) + (let [[sql & params] (format-in op (rest x))] + (into [(if nested? (str "(" sql ")") sql)] params)) (contains? @special-syntax op) (let [formatter (get @special-syntax op)] (formatter op (rest x))) @@ -651,13 +675,6 @@ {:valid-dialects (vec (sort (keys dialects)))}))) dialect) -(defn- unwrap [x opts] - (if-let [m (meta x)] - (if-let [f (::wrapper m)] - (f x opts) - x) - x)) - (defn format "Turn the data DSL into a vector containing a SQL string followed by any parameter values that were encountered in the DSL structure." @@ -675,7 +692,8 @@ (:inline opts)) *quoted* (if (contains? opts :quoted) (:quoted opts) - dialect?)] + dialect?) + *params* (:params opts)] (mapv #(unwrap % opts) (format-dsl data opts)))))) (defn set-dialect! From 0e2aae4a0054673d008f70eedcbc5cebb032b864 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 05:31:10 -0800 Subject: [PATCH 093/254] Fix :lift and test to use wrapper --- src/honey/sql.cljc | 3 ++- test/honey/sql/helpers_test.cljc | 2 +- 2 files changed, 3 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a1c275b..ea4fd40 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -563,7 +563,8 @@ (into [(str "INTERVAL " sql " " (sql-kw units))] params))) :lift (fn [_ [x]] - ["?" x]) + ["?" (with-meta (constantly x) + {::wrapper (fn [fx _] (fx))})]) :nest (fn [_ [x]] (format-expr x {:nested? true})) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 034b716..d610e5f 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -82,7 +82,7 @@ (-> (insert-into :foo) (columns :bar) - (values [[:lift {:baz "my-val"}]]) + (values [[[:lift {:baz "my-val"}]]]) sql/format))) (is (= ["INSERT INTO foo (a, b, c) VALUES (?, ?, ?), (?, ?, ?)" "a" "b" "c" "a" "b" "c"] From 63e4c8523f8f7467e6834e4fb9dd71d055b01dee Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 05:47:14 -0800 Subject: [PATCH 094/254] Fix CircleCI gitconfig --- .circleci/config.yml | 3 +++ 1 file changed, 3 insertions(+) diff --git a/.circleci/config.yml b/.circleci/config.yml index 387e56b..1b1f3cb 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -8,6 +8,9 @@ jobs: - checkout - restore_cache: key: honeysql-{{ checksum "deps.edn" }} + - run: + name: Get rid of erroneous git config + command: rm -rf ~/.gitconfig - run: name: Install Node command: sudo apt-get update && sudo apt-get install -y nodejs From ed86e7837c1951db67356ceca7b7ae53c036b783 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 05:51:55 -0800 Subject: [PATCH 095/254] Another attempt to fix CircleCI build --- .circleci/config.yml | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 1b1f3cb..86d0456 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -7,7 +7,7 @@ jobs: steps: - checkout - restore_cache: - key: honeysql-{{ checksum "deps.edn" }} + key: honeysql-v2-{{ checksum "deps.edn" }} - run: name: Get rid of erroneous git config command: rm -rf ~/.gitconfig @@ -25,7 +25,7 @@ jobs: - ~/.m2 - ~/.gitlibs - ~/node_modules - key: honeysql-{{ checksum "deps.edn" }} + key: honeysql-v2-{{ checksum "deps.edn" }} - run: name: Run all the tests command: sh run-tests.sh all From 3bde6cd8e7d1288a5ce93d838a90735a90ce3e73 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 06:00:27 -0800 Subject: [PATCH 096/254] Doh! CircleCI clojure tools was too old! --- .circleci/config.yml | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 86d0456..491cc03 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -3,11 +3,11 @@ jobs: build: working_directory: ~/honeysql docker: - - image: circleci/clojure:openjdk-11-tools-deps-1.10.0.442 + - image: circleci/clojure:openjdk-11-tools-deps-1.10.1.754 steps: - checkout - restore_cache: - key: honeysql-v2-{{ checksum "deps.edn" }} + key: honeysql-{{ checksum "deps.edn" }} - run: name: Get rid of erroneous git config command: rm -rf ~/.gitconfig @@ -25,7 +25,7 @@ jobs: - ~/.m2 - ~/.gitlibs - ~/node_modules - key: honeysql-v2-{{ checksum "deps.edn" }} + key: honeysql-{{ checksum "deps.edn" }} - run: name: Run all the tests command: sh run-tests.sh all From ad4256037032425aa2984b6939f5818bd197d2b4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 06:01:47 -0800 Subject: [PATCH 097/254] CircleCI -- node symlink no longer needed? --- .circleci/config.yml | 3 --- 1 file changed, 3 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 491cc03..53e9e15 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -14,9 +14,6 @@ jobs: - run: name: Install Node command: sudo apt-get update && sudo apt-get install -y nodejs - - run: - name: Add Node symlink - command: sudo ln -s /usr/bin/js /usr/bin/node - run: name: Download Dependencies command: clojure -Spath -R:test:runner:cljs-runner:eastwood:readme && clojure -Spath -A:1.9 From 97172103b49a5b72bfdbc5ad0d7ba557476c95b6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 06:05:09 -0800 Subject: [PATCH 098/254] Update CircleCI CLI usage --- .circleci/config.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 53e9e15..58af347 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -16,7 +16,7 @@ jobs: command: sudo apt-get update && sudo apt-get install -y nodejs - run: name: Download Dependencies - command: clojure -Spath -R:test:runner:cljs-runner:eastwood:readme && clojure -Spath -A:1.9 + command: clojure -P -A:test:runner:cljs-runner:eastwood:readme && clojure -P -A:1.9 - save_cache: paths: - ~/.m2 From 3439bb6c48ac6aba233eca011601297caca5392d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 31 Jan 2021 06:08:14 -0800 Subject: [PATCH 099/254] More CLI tweaking for CircleCI --- .circleci/config.yml | 2 +- deps.edn | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 58af347..234a5c4 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -16,7 +16,7 @@ jobs: command: sudo apt-get update && sudo apt-get install -y nodejs - run: name: Download Dependencies - command: clojure -P -A:test:runner:cljs-runner:eastwood:readme && clojure -P -A:1.9 + command: clojure -P -M:test:runner:cljs-runner:eastwood:readme && clojure -P -M:1.9 - save_cache: paths: - ~/.m2 diff --git a/deps.edn b/deps.edn index 92506fd..a5ab324 100644 --- a/deps.edn +++ b/deps.edn @@ -17,7 +17,7 @@ :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} - :eastwood {:extra-deps {jonase/eastwood {:mvn/version "RELEASE"}} + :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.13"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} :jar {:replace-deps {seancorfield/depstar {:mvn/version "2.0.171"}} :exec-fn hf.depstar/jar From 7aab640e30651c59844cfaa67f9f8c3a46d2bed8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 10:44:07 -0800 Subject: [PATCH 100/254] Fixes #291 by ensuring consistent values For uneven vectors of values, pad with NULLs. For uneven maps of values, use full set of keys across all of them. --- src/honey/sql.cljc | 22 +++++++++++++++++++--- test/honey/sql_test.cljc | 17 +++++++++++++---- 2 files changed, 32 insertions(+), 7 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index ea4fd40..b397024 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -315,17 +315,29 @@ (defn- format-values [k xs] (cond (sequential? (first xs)) ;; [[1 2 3] [4 5 6]] - (let [[sqls params] + (let [n-1 (map count xs) + ;; issue #291: ensure all value sequences are the same length + xs' (if (apply = n-1) + xs + (let [n-n (apply max n-1)] + (map (fn [x] (take n-n (concat x (repeat nil)))) xs))) + [sqls params] (reduce (fn [[sql params] [sqls' params']] [(conj sql (str "(" (str/join ", " sqls') ")")) (into params params')]) [[] []] - (map #'format-expr-list xs))] + (map #'format-expr-list xs'))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) (map? (first xs)) ;; [{:a 1 :b 2 :c 3}] - (let [cols (keys (first xs)) + (let [cols-1 (keys (first xs)) + ;; issue #291: check for all keys in all maps but still + ;; use the keys from the first map if they match so that + ;; users can rely on the key ordering if they want to, + ;; e.g., see test that uses array-map for the first row + cols-n (into #{} (mapcat keys) xs) + cols (if (= (set cols-1) cols-n) cols-1 cols-n) [sqls params] (reduce (fn [[sql params] [sqls' params']] [(conj sql (str "(" (str/join ", " sqls') ")")) @@ -347,6 +359,10 @@ (throw (ex-info ":values expects sequences or maps" {:first (first xs)})))) +(comment + (into #{} (mapcat keys) [{:a 1 :b 2} {:b 3 :c 4}]) + ,) + (defn- format-set-exprs [k xs] (let [[sqls params] (reduce-kv (fn [[sql params] v e] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 9af6179..8655bbd 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -102,14 +102,14 @@ ["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]]}]]}) + ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, NULL))" 1 2 3 4 5])) (is (= (format {:with [[[:static {:columns [:a :b :c]}] - {:values [[1 2 3] [4 5 6]]}]] + {:values [[1 2] [4 5 6]]}]] :select [:*] :from [:static]}) - ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, ?)) SELECT * FROM static" 1 2 3 4 5 6]))) + ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6]))) (deftest insert-into (is (= (format {:insert-into :foo}) @@ -134,6 +134,15 @@ {:namespace-as-table? true}) ["INSERT INTO foo (id) VALUES (?)" 2]))) +(deftest insert-into-uneven-maps + ;; we can't rely on ordering when the set of keys differs between maps: + (let [res (format {:insert-into :foo :values [{:id 1} {:id 2, :bar "quux"}]})] + (is (or (= res ["INSERT INTO foo (id, bar) VALUES (?, NULL), (?, ?)" 1 2 "quux"]) + (= res ["INSERT INTO foo (bar, id) VALUES (NULL, ?), (?, ?)" 1 "quux" 2])))) + (let [res (format {:insert-into :foo :values [{:id 1, :bar "quux"} {:id 2}]})] + (is (or (= res ["INSERT INTO foo (id, bar) VALUES (?, ?), (?, NULL)" 1 "quux" 2]) + (= res ["INSERT INTO foo (bar, id) VALUES (?, ?), (NULL, ?)" "quux" 1 2]))))) + (deftest exists-test ;; EXISTS should never have been implemented as SQL syntax: it's an operator! #_(is (= (format {:exists {:select [:a] :from [:foo]}}) From 2ef9d4dad28ae28eaa4fd7459da8c82c69d623e9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 12:00:42 -0800 Subject: [PATCH 101/254] Docstring overhaul --- CHANGELOG.md | 6 +++ src/honey/sql.cljc | 124 ++++++++++++++++++++++++++++++++------------- 2 files changed, 95 insertions(+), 35 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index c0450f4..051a49a 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,11 @@ # Changes +* 2.0.alpha in progress + * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: + * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. + * `honey.sql.helpers` -- provides a helper function for every piece of the DSL that is supported out-of-the-box. + * The coordinates for HoneySQL 2.0 are `seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.0 without any conflicts, making it easier to migrate piecemeal from 1.0 to 2.0. + * 1.0.444 -- 2020-05-29 * Fix #259 so column names are always unqualified in inserts. (@jrdoane) * Fix #257 by adding support for `cross-join` / `merge-cross-join` / `:cross-join`. (@dcj) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b397024..0fac9e5 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -1,7 +1,27 @@ ;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql - "Primary API for HoneySQL 2.x." + "Primary API for HoneySQL 2.x. + + This includes the `format` function -- the primary entry point -- as well + as several public formatters that are intended to help users extend the + supported syntax. + + In addition, functions to extend HoneySQL are also provided here: + * `sql-kw` -- turns a Clojure keyword into SQL code (makes it uppercase + and replaces - with space). + * `format-dsl` -- intended to format SQL statements; returns a vector + containing a SQL string followed by parameter values. + * `format-expr` -- intended to format SQL expressions; returns a vector + containing a SQL string followed by parameter values. + * `format-expr-list` -- intended to format a list of SQL expressions; + returns a pair comprising: a sequence of SQL expressions (to be + join with a delimiter) and a sequence of parameter values. + * `set-dialect!` -- set the default dialect to be used for formatting. + * `register-clause!` -- register a new statement/clause formatter. + * `register-fn!` -- register a new function call (or special syntax) + formatter. + * `register-op!` -- register a new operator formatter." (:refer-clojure :exclude [format]) (:require [clojure.string :as str])) @@ -83,7 +103,12 @@ #?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US)))) :cljs str/upper-case)) -(defn sql-kw [k] +(defn sql-kw + "Given a keyword, return a SQL representation of it as a string. + + A `:kebab-case` keyword becomes a `KEBAB CASE` (uppercase) string + with hyphens replaced by spaces, e.g., `:insert-into` => `INSERT INTO`." + [k] (-> k (name) (upper-case) (as-> s (if (= "-" s) s (str/replace s "-" " "))))) @@ -190,11 +215,24 @@ (map #(format-dsl % {:nested? true}) xs))] (into [(str/join (str " " (sql-kw k) " ") sqls)] params))) -(defn- format-expr-list [xs & [opts]] +(defn format-expr-list + "Given a sequence of expressions represented as data, return a pair + where the first element is a sequence of SQL fragments and the second + element is a sequence of parameters. The caller should join the SQL + fragments with whatever appropriate delimiter is needed and then + return a vector whose first element is the complete SQL string and + whose subsequent elements are the parameters: + + (let [[sqls params] (format-expr-list data opts)] + (into [(str/join delim sqls)] params)) + + This is intended to be used when writing your own formatters to + extend the DSL supported by HoneySQL." + [exprs & [opts]] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-expr % opts) xs))) + (map #(format-expr % opts) exprs))) (defn- format-columns [k xs] (let [[sqls params] (format-expr-list xs {:drop-ns? (= :columns k)})] @@ -444,27 +482,31 @@ (set @current-clause-order) (set (keys @clause-format)))) -(defn format-dsl [x & [{:keys [aliased? nested? pretty?]}]] +(defn format-dsl + "Given a hash map representing a SQL statement and a hash map + of options, return a vector containing a string -- the formatted + SQL statement -- followed by any parameter values that SQL needs. + + This is intended to be used when writing your own formatters to + extend the DSL supported by HoneySQL." + [statement-map & [{:keys [aliased? nested? pretty?]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] - (if-let [xs (or (k x) (let [s (symbol (name k))] (get x s)))] + (if-let [xs (or (k statement-map) + (let [s (symbol (name k))] + (get statement-map s)))] (let [formatter (k @clause-format) [sql' & params'] (formatter k xs)] [(conj sql sql') (if params' (into params params') params) (dissoc leftover k (symbol (name k)))]) [sql params leftover])) - [[] [] x] + [[] [] statement-map] *clause-order*)] (if (seq leftover) - (do - ;; TODO: for testing purposes, make this less noisy - (println (str "\n-------------------\nUnknown SQL clauses: " - (str/join ", " (keys leftover)))) - #_(throw (ex-info (str "Unknown SQL clauses: " - (str/join ", " (keys leftover))) - leftover)) - [(str "")]) + (throw (ex-info (str "Unknown SQL clauses: " + (str/join ", " (keys leftover))) + leftover)) (into [(cond-> (str/join (if pretty? "\n" " ") (filter seq sqls)) pretty? (as-> s (str "\n" s "\n")) @@ -606,22 +648,31 @@ (into [(str/join sqls)] params)) [s]))})) -(defn format-expr [x & [{:keys [nested?] :as opts}]] - (cond (or (keyword? x) (symbol? x)) - (format-var x opts) +(defn format-expr + "Given a data structure that represents a SQL expression and a hash + map of options, return a vector containing a string -- the formatted + SQL statement -- followed by any parameter values that SQL needs. - (map? x) - (format-dsl x (assoc opts :nested? true)) + This is intended to be used when writing your own formatters to + extend the DSL supported by HoneySQL." + [expr & [{:keys [nested?] :as opts}]] + (cond (or (keyword? expr) (symbol? expr)) + (format-var expr opts) - (sequential? x) - (let [op (first x) + (map? expr) + (format-dsl expr (assoc opts :nested? true)) + + (sequential? expr) + (let [op (first expr) ;; normalize symbols to keywords here -- makes the subsequent ;; logic easier since we use op to lookup things in hash maps: op (if (symbol? op) (keyword (name op)) op)] (if (keyword? op) (cond (contains? @infix-ops op) (if (contains? @op-variadic op) ; no aliases here, no special semantics - (let [x (if (contains? @op-ignore-nil op) (remove nil? x) x) + (let [x (if (contains? @op-ignore-nil op) + (remove nil? expr) + expr) [sqls params] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') @@ -633,12 +684,12 @@ nested? (as-> s (str "(" s ")")))] params)) - (let [[_ a b & y] x + (let [[_ a b & y] expr _ (when (seq y) (throw (ex-info (str "only binary " op " is supported") - {:expr x}))) + {:expr expr}))) [s1 & p1] (format-expr a {:nested? true}) [s2 & p2] (format-expr b {:nested? true}) op (get infix-aliases op op)] @@ -657,13 +708,13 @@ (into p1) (into p2))))) (contains? #{:in :not-in} op) - (let [[sql & params] (format-in op (rest x))] + (let [[sql & params] (format-in op (rest expr))] (into [(if nested? (str "(" sql ")") sql)] params)) (contains? @special-syntax op) (let [formatter (get @special-syntax op)] - (formatter op (rest x))) + (formatter op (rest expr))) :else - (let [args (rest x) + (let [args (rest expr) [sqls params] (format-expr-list args)] (into [(str (sql-kw op) (if (and (= 1 (count args)) @@ -672,19 +723,19 @@ (str " " (first sqls)) (str "(" (str/join ", " sqls) ")")))] params))) - (let [[sqls params] (format-expr-list x)] + (let [[sqls params] (format-expr-list expr)] (into [(str "(" (str/join ", " sqls) ")")] params)))) - (boolean? x) - [(upper-case (str x))] + (boolean? expr) + [(upper-case (str expr))] - (nil? x) + (nil? expr) ["NULL"] :else (if *inline* - [(sqlize-value x)] - ["?" x]))) + [(sqlize-value expr)] + ["?" expr]))) (defn- check-dialect [dialect] (when-not (contains? dialects dialect) @@ -694,7 +745,10 @@ (defn format "Turn the data DSL into a vector containing a SQL string followed by - any parameter values that were encountered in the DSL structure." + any parameter values that were encountered in the DSL structure. + + This is the primary API for HoneySQL and handles dialects, quoting, + and named parameters." ([data] (format data {})) ([data opts] (let [dialect? (contains? opts :dialect) From 379d3d05c48f1b3d28d44065e40e22b965754813 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 13:10:57 -0800 Subject: [PATCH 102/254] Drop ? from all keyword options --- README.md | 19 +++++----- src/honey/sql.cljc | 80 ++++++++++++++++++++-------------------- test/honey/sql_test.cljc | 18 ++++----- 3 files changed, 58 insertions(+), 59 deletions(-) diff --git a/README.md b/README.md index 873757c..dad105d 100644 --- a/README.md +++ b/README.md @@ -17,8 +17,7 @@ This is the README for the upcoming 2.x version of HoneySQL which provides a str All sample code in this README is automatically run as a unit test using [seancorfield/readme](https://github.com/seancorfield/readme). -Note that while some of these samples show pretty-printed SQL, this is just for -README readability; honeysql does not generate pretty-printed SQL. +Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty true` which inserts newlines between clauses in the generated SQL strings. ## Usage @@ -154,7 +153,7 @@ then provide a collection of rows, each a collection of column values: [["Jon" "Smith" 34] ["Andrew" "Cooper" 12] ["Jane" "Daniels" 56]]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" INSERT INTO properties (name, surname, age) @@ -172,7 +171,7 @@ and the remaining maps *must* have the same set of keys and values: (values [{:name "John" :surname "Smith" :age 34} {:name "Andrew" :surname "Cooper" :age 12} {:name "Jane" :surname "Daniels" :age 56}]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" INSERT INTO properties (name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) @@ -194,7 +193,7 @@ The column values do not have to be literals, they can be nested queries: :role_id (-> (select :id) (from :role) (where [:= :name role-name]))}]) - (sql/format {:pretty? true}))) + (sql/format {:pretty true}))) => [" INSERT INTO user_profile_to_role @@ -222,7 +221,7 @@ Composite types are supported: (values [["small" (composite 1 "inch")] ["large" (composite 10 "feet")]]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" INSERT INTO comp_table (name, comp_column) @@ -240,7 +239,7 @@ Updates are possible too: (set {:kind "dramatic" :watched [:+ :watched 1]}) (where [:= :kind "drama"]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" UPDATE films SET kind = ?, watched = watched + ? @@ -276,7 +275,7 @@ If your database supports it, you can also delete from multiple tables: (from :films) (join :directors [:= :films.director_id :directors.id]) (where [:<> :kind "musical"]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" DELETE films, directors FROM films @@ -363,7 +362,7 @@ have a lot of function calls needed in code: (values [{:location [:ST_SetSRID [:ST_MakePoint 0.291 32.621] [:cast 4325 :integer]]}]) - (sql/format {:pretty? true})) + (sql/format {:pretty true})) => [" INSERT INTO sample (location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS integer))) @@ -523,7 +522,7 @@ big-complicated-map ```clojure (sql/format big-complicated-map {:params {:param1 "gabba" :param2 2} - :pretty? true}) + :pretty true}) => [" SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0fac9e5..64de08b 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -115,13 +115,13 @@ (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) -(defn- format-entity [x & [{:keys [aliased? drop-ns?]}]] +(defn- format-entity [x & [{:keys [aliased drop-ns]}]] (let [nn (if (or *quoted* (string? x)) name name-_) q (if (or *quoted* (string? x)) (:quote *dialect*) identity) - [t c] (if-let [n (when-not (or drop-ns? (string? x)) + [t c] (if-let [n (when-not (or drop-ns (string? x)) (namespace-_ x))] [n (nn x)] - (if aliased? + (if aliased [nil (nn x)] (let [[t c] (str/split (nn x) #"\.")] (if c [t c] [nil t]))))] @@ -162,30 +162,30 @@ (cond-> (format-entity s) pair? (str (if (and (contains? *dialect* :as) (not (:as *dialect*))) " " " AS ") - (format-entity (second x) {:aliased? true})))) + (format-entity (second x) {:aliased true})))) :else (format-entity x))) -(defn- format-selectable-dsl [x & [{:keys [as? aliased?] :as opts}]] +(defn- format-selectable-dsl [x & [{:keys [as aliased] :as opts}]] (cond (map? x) - (format-dsl x {:nested? true}) + (format-dsl x {:nested true}) (sequential? x) (let [s (first x) pair? (< 1 (count x)) a (second x) [sql & params] (if (map? s) - (format-dsl s {:nested? true}) + (format-dsl s {:nested true}) (format-expr s)) [sql' & params'] (when pair? (if (sequential? a) - (let [[sql params] (format-expr-list a {:aliased? true})] + (let [[sql params] (format-expr-list a {:aliased true})] (into [(str/join " " sql)] params)) - (format-selectable-dsl a {:aliased? true})))] + (format-selectable-dsl a {:aliased true})))] (-> [(cond-> sql pair? - (str (if as? + (str (if as (if (and (contains? *dialect* :as) (not (:as *dialect*))) " " @@ -195,11 +195,11 @@ (into params'))) (or (keyword? x) (symbol? x)) - (if aliased? + (if aliased [(format-entity x opts)] (format-var x opts)) - (and aliased? (string? x)) + (and aliased (string? x)) [(format-entity x opts)] :else @@ -212,7 +212,7 @@ (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-dsl % {:nested? true}) xs))] + (map #(format-dsl % {:nested true}) xs))] (into [(str/join (str " " (sql-kw k) " ") sqls)] params))) (defn format-expr-list @@ -235,7 +235,7 @@ (map #(format-expr % opts) exprs))) (defn- format-columns [k xs] - (let [[sqls params] (format-expr-list xs {:drop-ns? (= :columns k)})] + (let [[sqls params] (format-expr-list xs {:drop-ns (= :columns k)})] (into [(str "(" (str/join ", " sqls) ")")] params))) (defn- format-selects [k xs] @@ -244,9 +244,9 @@ (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-selectable-dsl % {:as? (#{:select :from} k)}) xs))] + (map #(format-selectable-dsl % {:as (#{:select :from} k)}) xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) - (let [[sql & params] (format-selectable-dsl xs {:as? (#{:select :from} k)})] + (let [[sql & params] (format-selectable-dsl xs {:as (#{:select :from} k)})] (into [(str (sql-kw k) " " sql)] params)))) (defn- format-with-part [x] @@ -386,7 +386,7 @@ xs))] (into [(str "(" (str/join ", " - (map #(format-entity % {:drop-ns? true}) cols)) + (map #(format-entity % {:drop-ns true}) cols)) ") " (sql-kw k) " " @@ -419,7 +419,7 @@ (defn- format-do-update-set [k x] (if (or (keyword? x) (symbol? x)) - (let [e (format-entity x {:drop-ns? true})] + (let [e (format-entity x {:drop-ns true})] [(str (sql-kw k) " " e " = EXCLUDED." e)]) (format-set-exprs k x))) @@ -489,7 +489,7 @@ This is intended to be used when writing your own formatters to extend the DSL supported by HoneySQL." - [statement-map & [{:keys [aliased? nested? pretty?]}]] + [statement-map & [{:keys [aliased nested pretty]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] (if-let [xs (or (k statement-map) @@ -507,10 +507,10 @@ (throw (ex-info (str "Unknown SQL clauses: " (str/join ", " (keys leftover))) leftover)) - (into [(cond-> (str/join (if pretty? "\n" " ") (filter seq sqls)) - pretty? + (into [(cond-> (str/join (if pretty "\n" " ") (filter seq sqls)) + pretty (as-> s (str "\n" s "\n")) - (and nested? (not aliased?)) + (and nested (not aliased)) (as-> s (str "(" s ")")))] params)))) (def ^:private infix-aliases @@ -552,8 +552,8 @@ x)) (defn- format-in [in [x y]] - (let [[sql-x & params-x] (format-expr x {:nested? true}) - [sql-y & params-y] (format-expr y {:nested? true}) + (let [[sql-x & params-x] (format-expr x {:nested true}) + [sql-y & params-y] (format-expr y {:nested true}) values (unwrap (first params-y) {})] (if (and (= "?" sql-y) (= 1 (count params-y)) (coll? values)) (let [sql (str "(" (str/join ", " (repeat (count values) "?")) ")")] @@ -572,9 +572,9 @@ (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) :between (fn [_ [x a b]] - (let [[sql-x & params-x] (format-expr x {:nested? true}) - [sql-a & params-a] (format-expr a {:nested? true}) - [sql-b & params-b] (format-expr b {:nested? true})] + (let [[sql-x & params-x] (format-expr x {:nested true}) + [sql-a & params-a] (format-expr a {:nested true}) + [sql-b & params-b] (format-expr b {:nested true})] (-> [(str sql-x " BETWEEN " sql-a " AND " sql-b)] (into params-x) (into params-a) @@ -625,7 +625,7 @@ {::wrapper (fn [fx _] (fx))})]) :nest (fn [_ [x]] - (format-expr x {:nested? true})) + (format-expr x {:nested true})) :not (fn [_ [x]] (let [[sql & params] (format-expr x)] @@ -655,12 +655,12 @@ This is intended to be used when writing your own formatters to extend the DSL supported by HoneySQL." - [expr & [{:keys [nested?] :as opts}]] + [expr & [{:keys [nested] :as opts}]] (cond (or (keyword? expr) (symbol? expr)) (format-var expr opts) (map? expr) - (format-dsl expr (assoc opts :nested? true)) + (format-dsl expr (assoc opts :nested true)) (sequential? expr) (let [op (first expr) @@ -678,10 +678,10 @@ [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-expr % {:nested? true}) + (map #(format-expr % {:nested true}) (rest x)))] (into [(cond-> (str/join (str " " (sql-kw op) " ") sqls) - nested? + nested (as-> s (str "(" s ")")))] params)) (let [[_ a b & y] expr @@ -690,26 +690,26 @@ op " is supported") {:expr expr}))) - [s1 & p1] (format-expr a {:nested? true}) - [s2 & p2] (format-expr b {:nested? true}) + [s1 & p1] (format-expr a {:nested true}) + [s2 & p2] (format-expr b {:nested true}) op (get infix-aliases op op)] (if (and (#{:= :<>} op) (or (nil? a) (nil? b))) (-> (str (if (nil? a) (if (nil? b) "NULL" s2) s1) (if (= := op) " IS NULL" " IS NOT NULL")) - (cond-> nested? + (cond-> nested (as-> s (str "(" s ")"))) (vector)) (-> (str s1 " " (sql-kw op) " " s2) - (cond-> nested? + (cond-> nested (as-> s (str "(" s ")"))) (vector) (into p1) (into p2))))) (contains? #{:in :not-in} op) (let [[sql & params] (format-in op (rest expr))] - (into [(if nested? (str "(" sql ")") sql)] params)) + (into [(if nested (str "(" sql ")") sql)] params)) (contains? @special-syntax op) (let [formatter (get @special-syntax op)] (formatter op (rest expr))) @@ -849,7 +849,7 @@ (format {:select [:*] :from [:table] :order-by [[[:date :expiry] :desc] :bar]} {}) (println (format {:select [:*] :from [:table] - :order-by [[[:date :expiry] :desc] :bar]} {:pretty? true})) + :order-by [[[:date :expiry] :desc] :bar]} {:pretty true})) (format {:select [:*] :from [:table] :where [:< [:date_add :expiry [:interval 30 :days]] [:now]]} {}) (format-expr [:interval 30 :days]) @@ -859,10 +859,10 @@ :where [:= :id (with-meta (constantly 42) {:foo true})]} {:dialect :mysql})) (println (format {:select [:*] :from [:table] - :where [:in :id [1 2 3 4]]} {:pretty? true})) + :where [:in :id [1 2 3 4]]} {:pretty true})) (println (format {:select [:*] :from [:table] :where [:and [:in :id [1 [:param :foo]]] [:= :bar [:param :quux]]]} {:params {:foo 42 :quux 13} - :pretty? true})) + :pretty true})) ,) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 8655bbd..56c4d45 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -477,14 +477,14 @@ VALUES ('UA502', 'Bananas', 105, '1971-07-13', 'Comedy', '82 minutes') :values [[[:inline "UA502"] [:inline "Bananas"] [:inline 105] [:inline "1971-07-13"] [:inline "Comedy"] [:inline "82 minutes"]]]} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO films VALUES (?, ?, ?, ?, ?, ?) " "UA502", "Bananas", 105, "1971-07-13", "Comedy", "82 minutes"] (format {:insert-into :films :values [["UA502" "Bananas" 105 "1971-07-13" "Comedy" "82 minutes"]]} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO films (code, title, did, date_prod, kind) @@ -493,14 +493,14 @@ VALUES (?, ?, ?, ?, ?) (format {:insert-into :films :columns [:code :title :did :date_prod :kind] :values [["T_601", "Yojimo", 106, "1961-06-16", "Drama"]]} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO films VALUES (?, ?, ?, DEFAULT, ?, ?) " "UA502", "Bananas", 105, "Comedy", "82 minutes"] (format {:insert-into :films :values [["UA502" "Bananas" 105 [:default] "Comedy" "82 minutes"]]} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO films (code, title, did, date_prod, kind) @@ -509,7 +509,7 @@ VALUES (?, ?, ?, DEFAULT, ?) (format {:insert-into :films :columns [:code :title :did :date_prod :kind] :values [["T_601", "Yojimo", 106, [:default], "Drama"]]} - {:pretty? true})))) + {:pretty true})))) (deftest on-conflict-tests ;; these examples are taken from https://www.postgresqltutorial.com/postgresql-upsert/ @@ -525,7 +525,7 @@ DO NOTHING :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] :on-conflict {:on-constraint :customers_name_key} :do-nothing true} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO customers (name, email) @@ -538,7 +538,7 @@ DO NOTHING :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] :on-conflict :name :do-nothing true} - {:pretty? true}))) + {:pretty true}))) (is (= [" INSERT INTO customers (name, email) @@ -551,7 +551,7 @@ DO UPDATE SET email = EXCLUDED.email || ';' || customers.email :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] :on-conflict :name :do-update-set {:email [:|| :EXCLUDED.email [:inline ";"] :customers.email]}} - {:pretty? true})))) + {:pretty true})))) (deftest issue-285 (is (= [" @@ -564,4 +564,4 @@ ORDER BY id = ? DESC (h/from :processes) (h/where [:= :state 42]) (h/order-by [[:= :id 123] :desc])) - {:pretty? true})))) + {:pretty true})))) From 53bcfd8beaabcc7ebac5a0a328ab6c9076793af7 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 14:49:17 -0800 Subject: [PATCH 103/254] Move toward 2.0.0 Alpha 1 --- CHANGELOG.md | 4 +- README.md | 180 +++++++++++++++---------------- pom.xml | 4 +- src/honey/sql.cljc | 2 +- src/honey/sql/helpers.cljc | 13 ++- test/honey/sql/helpers_test.cljc | 6 +- test/honey/sql_test.cljc | 7 +- 7 files changed, 109 insertions(+), 107 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 051a49a..5a611b2 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,11 +1,13 @@ # Changes -* 2.0.alpha in progress +* 2.0.0-alpha1 (for early testing) * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. * `honey.sql.helpers` -- provides a helper function for every piece of the DSL that is supported out-of-the-box. * The coordinates for HoneySQL 2.0 are `seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.0 without any conflicts, making it easier to migrate piecemeal from 1.0 to 2.0. +# HoneySQL pre-2.x Changes + * 1.0.444 -- 2020-05-29 * Fix #259 so column names are always unqualified in inserts. (@jrdoane) * Fix #257 by adding support for `cross-join` / `merge-cross-join` / `:cross-join`. (@dcj) diff --git a/README.md b/README.md index dad105d..f8dd2c1 100644 --- a/README.md +++ b/README.md @@ -6,7 +6,7 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim The latest stable version (1.0.444) on Clojars and on cljdoc: -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.next)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. @@ -25,7 +25,7 @@ Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty tr (refer-clojure :exclude '[for group-by set update]) (require '[honey.sql :as sql] ;; caution: this overwrites for, group-by, set, and update - '[honey.sql.helpers :refer :all :as helpers]) + '[honey.sql.helpers :refer :all :as h]) ``` Everything is built on top of maps representing SQL queries: @@ -57,18 +57,16 @@ to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jd If you want to format the query as a string with no parameters (e.g. to use the SQL statement in a SQL console), pass `:inline true` as an option to `sql/format`: -```clj +```clojure (sql/format sqlmap {:inline true}) => ["SELECT a, b, c FROM foo WHERE f.a = 'baz'"] ``` > Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you. -_The handling of namespace-qualified keywords is under review in 2.x._ +Namespace-qualified keywords are generally treated as table-qualified columns: `:foo/bar` becomes `foo.bar`, except in contexts where that would be illegal (such as the list of columns in an `INSERT` statement). This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. -By default, namespace-qualified keywords are treated as simple keywords: their namespace portion is ignored. This was the behavior in HoneySQL prior to the 0.9.0 release and has been restored since the 0.9.7 release as this is considered the least surprising behavior. -As of version 0.9.7, `format` accepts `:allow-namespaced-names? true` to provide the somewhat unusual behavior of 0.9.0-0.9.6, namely that namespace-qualified keywords were passed through into the SQL "as-is", i.e., with the `/` in them (which generally required a quoting strategy as well). -As of version 0.9.8, `format` accepts `:namespace-as-table? true` to treat namespace-qualified keywords as if the `/` were `.`, allowing `:table/column` as an alternative to `:table.column`. This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. +_[In HoneySQL 1.x, this was the behavior when `:namespace-as-table? true` was specified]_ ```clojure (def q-sqlmap {:select [:foo/a :foo/b :foo/c] @@ -80,8 +78,6 @@ As of version 0.9.8, `format` accepts `:namespace-as-table? true` to treat names ### Vanilla SQL clause helpers -_The code behind this section is a work-in-progress._ - There are also functions for each clause type in the `honey.sql.helpers` namespace: ```clojure @@ -98,7 +94,7 @@ Order doesn't matter (for independent clauses): => true ``` -When using the vanilla helper functions, repeated clauses will be merged into existing clauses (where that makes sense): +When using the vanilla helper functions, repeated clauses will be merged into existing clauses, in the natural evaluation order (where that makes sense): ```clojure (-> sqlmap (select :d)) @@ -138,7 +134,8 @@ name and the desired alias: ``` In particular, note that `(select [:a :b])` means `SELECT a AS b` rather than -`SELECT a, b` -- `select` is variadic and does not take a collection of column names. +`SELECT a, b` -- helpers like `select` are generally variadic and do not take +a collection of column names. ### Inserts @@ -162,9 +159,9 @@ VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] ``` +If the rows are of unequal lengths, they will be padded with `NULL` values to make them consistent. -Alternately, you can simply specify the values as maps; the first map defines the columns to insert, -and the remaining maps *must* have the same set of keys and values: +Alternately, you can simply specify the values as maps: ```clojure (-> (insert-into :properties) @@ -181,6 +178,9 @@ INSERT INTO properties "Jane" "Daniels" 56] ``` +The set of columns used in the insert will be the union of all column names from all +the hash maps: columns that are missing from any rows will have `NULL` as their value. + ### Nested subqueries The column values do not have to be literals, they can be nested queries: @@ -235,7 +235,7 @@ VALUES (?, (?, ?)), (?, (?, ?)) Updates are possible too: ```clojure -(-> (helpers/update :films) +(-> (h/update :films) (set {:kind "dramatic" :watched [:+ :watched 1]}) (where [:= :kind "drama"]) @@ -295,7 +295,7 @@ If you want to delete everything from a table, you can use `truncate`: ### Set operations -Queries may be combined within a :union, :union-all, :intersect or :except keyword: +Queries may be combined with a `:union`, `:union-all`, `:intersect` or `:except` keyword: ```clojure (sql/format {:union [(-> (select :*) (from :foo)) @@ -303,23 +303,43 @@ Queries may be combined within a :union, :union-all, :intersect or :except keywo => ["(SELECT * FROM foo) UNION (SELECT * FROM bar)"] ``` +There are also helpers for each of those: + +```clojure +(sql/format (union (-> (select :*) (from :foo)) + (-> (select :*) (from :bar)))) +=> ["(SELECT * FROM foo) UNION (SELECT * FROM bar)"] +``` + + ### Functions Keywords that begin with `%` are interpreted as SQL function calls: ```clojure (-> (select :%count.*) (from :foo) sql/format) -=> ["SELECT count(*) FROM foo"] +=> ["SELECT COUNT(*) FROM foo"] ``` ```clojure (-> (select :%max.id) (from :foo) sql/format) -=> ["SELECT max(id) FROM foo"] +=> ["SELECT MAX(id) FROM foo"] +``` + +Since regular function calls are indicated with vectors and so are aliased pairs, +this shorthand can be more convenient due to the extra wrapping needed for the +regular function calls in a select: + +```clojure +(-> (select [[:count :*]]) (from :foo) sql/format) +=> ["SELECT COUNT(*) FROM foo"] +``` +```clojure +(-> (select [[:max :id]]) (from :foo) sql/format) +=> ["SELECT MAX(id) FROM foo"] ``` ### Bindable parameters -_This is not currently supported._ - Keywords that begin with `?` are interpreted as bindable parameters: ```clojure @@ -332,8 +352,29 @@ Keywords that begin with `?` are interpreted as bindable parameters: ### Miscellaneous -TODO: need to update this section to reflect how to select a function call, how -to identify inline parameter values, and how to add in raw SQL fragments! +Sometimes you want to provide SQL fragments directly or have certain values +placed into the SQL string rather than turned into a parameter. + +The `:raw` syntax lets you embed SQL fragments directly into a HoneySQL expression. +It accepts either a single string to embed or a vector of expressions that will be +converted to strings and embedded as a single string. + +The `:inline` syntax attempts to turn a Clojure value into a SQL value and then +embeds that string, e.g., `[:inline "foo"]` produces `'foo'` (a SQL string). + +The `:param` syntax identifies a named parameter whose value will be supplied +via the `:params` argument to `format`. + +The `:lift` syntax will prevent interpretation of Clojure data structures as +part of the DSL and instead turn such values into parameters (useful when you +want to pass a vector or a hash map directly as a positional parameter value, +for example when you have extended `next.jdbc`'s `SettableParameter` protocol +to a data structure). + +Finally, the `:nest` syntax will cause an extra set of parentheses to be +wrapped around its argument, after formatting that argument as a SQL expression. + +These can be combined to allow more fine-grained control over SQL generation: ```clojure (def call-qualify-map @@ -352,36 +393,6 @@ call-qualify-map => ["SELECT FOO(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"] ``` -#### PostGIS - -A common example in the wild is the PostGIS extension to PostgreSQL where you -have a lot of function calls needed in code: - -```clojure -(-> (insert-into :sample) - (values [{:location [:ST_SetSRID - [:ST_MakePoint 0.291 32.621] - [:cast 4325 :integer]]}]) - (sql/format {:pretty true})) -=> [" -INSERT INTO sample -(location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS integer))) -" -0.291 32.621 4325] -``` - -#### Raw SQL fragments - -_This functionality is under review._ - -Raw SQL fragments that are strings are treated exactly as-is when rendered into -the formatted SQL string (with no parsing or parameterization). Inline values -will not be lifted out as parameters, so they end up in the SQL string as-is. - -Raw SQL can also be supplied as a vector of strings and values. Strings are -rendered as-is into the formatted SQL string. Non-strings are lifted as -parameters. If you need a string parameter lifted, you must use `:param`. - ```clojure (-> (select :*) (from :foo) @@ -414,6 +425,24 @@ parameters. If you need a string parameter lifted, you must use `:param`. => ["SELECT * FROM foo WHERE expired_at < now() - '5 seconds'"] ``` +#### PostGIS + +A common example in the wild is the PostGIS extension to PostgreSQL where you +have a lot of function calls needed in code: + +```clojure +(-> (insert-into :sample) + (values [{:location [:ST_SetSRID + [:ST_MakePoint 0.291 32.621] + [:cast 4325 :integer]]}]) + (sql/format {:pretty true})) +=> [" +INSERT INTO sample +(location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS integer))) +" +0.291 32.621 4325] +``` + #### Identifiers To quote identifiers, pass the `:quoted true` option to `format` and they will @@ -435,17 +464,17 @@ Valid `:dialect` options are `:ansi` (the default, use this for PostgreSQL), The ANSI/PostgreSQL/SQLServer dialects support locking selects via a `FOR` clause as follows: -* `:for [ ]` where `` is required and may be one of: +* `:for [ ]` where `` is required and may be one of: * `:update` * `:no-key-update` * `:share` * `:key-share` -* Both `` and `` are optional but if present, `` must either be: +* Both `` and `` are optional but if present, `` must either be: * a single table name (as a keyword) or * a sequence of table names (as keywords) -* `` must be `:nowait` if it is present. +* `` can be `:nowait`, `:wait`, `:skip-locked` etc. -If `` and `` are both omitted, you may also omit the `[`..`]` and just say `:for :update` etc. +If `` and `` are both omitted, you may also omit the `[`..`]` and just say `:for :update` etc. ```clojure (-> (select :foo.a) @@ -466,20 +495,20 @@ If the `:mysql` dialect is selected, an additional locking clause is available: => ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"] ``` -To be able to use dashes in quoted names, you can pass ```:allow-dashed-names true``` as an argument to the ```format``` function. +Dashes are allowed in quoted names: + ```clojure (sql/format {:select [:f.foo-id :f.foo-name] :from [[:foo-bar :f]] :where [:= :f.foo-id 12345]} - {:allow-dashed-names? true ; not implemented yet - :quoted true}) + {:quoted true}) => ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" AS \"f\" WHERE \"f\".\"foo-id\" = ?" 12345] ``` ### Big, complicated example -Here's a big, complicated query. Note that Honey SQL makes no attempt to verify that your queries make any sense. It merely renders surface syntax. +Here's a big, complicated query. Note that HoneySQL makes no attempt to verify that your queries make any sense. It merely renders surface syntax. ```clojure (def big-complicated-map @@ -546,7 +575,7 @@ OFFSET ? ## Extensibility -Any keyword (or symbol) that appears as the first element of a vector will be treated as a generic function unless it is declared to be an operator or "special syntax". Any keyword (or symbol) that appears as a key in a hash map will be treated as a SQL clause -- and must either be built-in or must be registered as new clauses. +Any keyword (or symbol) that appears as the first element of a vector will be treated as a generic function unless it is declared to be an operator or "special syntax". Any keyword (or symbol) that appears as a key in a hash map will be treated as a SQL clause -- and must either be built-in or must be registered as a new clause. If your database supports `<=>` as an operator, you can tell HoneySQL about it using the `register-op!` function (which should be called before the first call to `honey.sql/format`): @@ -610,37 +639,6 @@ You can also register SQL clauses, specifying the keyword, the formatting functi If you find yourself registering an operator, a function (syntax), or a new clause, consider submitting a [pull request to HoneySQL](https://github.com/seancorfield/honeysql/pulls) so others can use it, too. If it is dialect-specific, let me know in the pull request. -## Why does my parameter get emitted as `()`? - -_Need to investigate whether this is still true in 2.0!_ - -If you want to use your own datatype as a parameter then the idiomatic approach of implementing -`next.jdbc`'s [`SettableParameter`](https://cljdoc.org/d/seancorfield/next.jdbc/CURRENT/api/next.jdbc.prepare#SettableParameter) -or `clojure.java.jdbc`'s [`ISQLValue`](https://clojure.github.io/java.jdbc/#clojure.java.jdbc/ISQLValue) protocol isn't enough as HoneySQL won't correct pass through your datatype, rather it will interpret it incorrectly. - -_This bit no longer exists:_ - -To teach HoneySQL how to handle your datatype you need to implement [`honeysql.format/ToSql`](https://github.com/seancorfield/honeysql/blob/a9dffec632be62c961be7d9e695d0b2b85732c53/src/honeysql/format.cljc#L94). For example: - -``` clojure -;; given: -(defrecord MyDateWrapper [...] - (to-sql-timestamp [this]...) -) - -;; executing: -(hsql/format {:where [:> :some_column (MyDateWrapper. ...)]}) -;; results in => "where :some_column > ()" - -;; we can teach honeysql about it: -(extend-protocol honeysql.format/ToSql - MyDateWrapper - (to-sql [v] (to-sql (date/to-sql-timestamp v)))) - -;; allowing us to now: -(hsql/format {:where [:> :some_column (MyDateWrapper. ...)]}) -;; which correctly results in => "where :some_column>?" and the parameter correctly set -``` ## TODO - [ ] Create table, etc. diff --git a/pom.xml b/pom.xml index 6fa4e12..9114dc8 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 seancorfield honeysql - 2.0.next + 2.0.0-alpha1 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.next + v2.0.0-alpha1 diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 64de08b..59251d1 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -146,7 +146,7 @@ (cond (= \% (first c)) (let [[f & args] (str/split (subs c 1) #"\.")] ;; TODO: this does not quote arguments -- does that matter? - [(str f "(" (str/join "," args) ")")]) + [(str (upper-case f) "(" (str/join "," args) ")")]) (= \? (first c)) ["?" (->param (keyword (subs c 1)))] :else diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index bb429a1..e5ff1f9 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -46,11 +46,14 @@ (defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) -(defn intersect [& args] (generic :intersect args)) -(defn union [& args] (generic :union args)) -(defn union-all [& args] (generic :union-all args)) -(defn except [& args] (generic :except args)) -(defn except-all [& args] (generic :except-all args)) +;; these five need to supply an empty hash map since they wrap +;; all of their arguments: +(defn intersect [& args] (generic :intersect (cons {} args))) +(defn union [& args] (generic :union (cons {} args))) +(defn union-all [& args] (generic :union-all (cons {} args))) +(defn except [& args] (generic :except (cons {} args))) +(defn except-all [& args] (generic :except-all (cons {} args))) + (defn select [& args] (generic :select args)) (defn select-distinct [& args] (generic :select-distinct args)) (defn insert-into [& args] (generic :insert-into args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index d610e5f..b1e313c 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -54,17 +54,17 @@ (testing "Various construction methods are consistent" (is (= m1 m2))) (testing "SQL data formats correctly" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) #?(:clj (testing "SQL data prints and reads correctly" (is (= m1 (read-string (pr-str m1)))))) #_(testing "SQL data formats correctly with alternate param naming" (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) - ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" + ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) (testing "Locking" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla `bla-bla`, now(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] (sql/format (assoc m1 :lock [:in-share-mode]) {:params {:param1 "gabba" :param2 2} diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 56c4d45..714f775 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -52,7 +52,6 @@ (deftest general-tests (is (= ["SELECT * FROM \"table\" WHERE \"id\" = ?" 1] (sut/format {:select [:*] :from [:table] :where [:= :id 1]} {:quoted true}))) - ;; temporarily remove AS from alias here (is (= ["SELECT \"t\".* FROM \"table\" AS \"t\" WHERE \"id\" = ?" 1] (sut/format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {:quoted true}))) (is (= ["SELECT * FROM \"table\" GROUP BY \"foo\", \"bar\""] @@ -226,18 +225,18 @@ :where [:= [:mod :col1 4] [:+ :col2 4]]})))) (testing "Example from dharrigan" - (is (= ["SELECT pg_try_advisory_lock(1)"] + (is (= ["SELECT PG_TRY_ADVISORY_LOCK(1)"] (format {:select [:%pg_try_advisory_lock.1]})))) (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"] + (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"] + (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] From 469e5a393e68015501f142d8ce7f80569993707f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 15:09:27 -0800 Subject: [PATCH 104/254] Link to differences; fix clojars/cljdoc links etc --- README.md | 10 ++++++++-- 1 file changed, 8 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index f8dd2c1..e8ab2f2 100644 --- a/README.md +++ b/README.md @@ -4,14 +4,20 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -The latest stable version (1.0.444) on Clojars and on cljdoc: +The latest stable version (1.0.444) on Clojars and on cljdoc (note: `honeysql/honeysql`): -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) +[![Clojars Project](https://clojars.org/honeysql/honeysql/latest-version.svg)](https://clojars.org/honeysql/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.444)](https://cljdoc.org/d/honeysql/honeysql/CURRENT) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. +Prerelease builds of the upcoming 2.x version of HoneySQL will soon be available: + +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) + This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). +See this [summary of differences between v1 and v2](https://github.com/seancorfield/honeysql/blob/v2/doc/differences-from-1-x.md) if you want to help test v2! + ## Note on code samples All sample code in this README is automatically run as a unit test using From d7c7f15a6b4115003798037fea44ef24f5077a72 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 16:24:00 -0800 Subject: [PATCH 105/254] Final de-?-ing keyword arguments/options --- src/honey/sql.cljc | 12 +++++++++--- 1 file changed, 9 insertions(+), 3 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 59251d1..1f8e0f8 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -823,12 +823,12 @@ "Register a new infix operator. Operators can be defined to be variadic (the default is that they are binary) and may choose to ignore `nil` arguments (this can make it easier to programmatically construct the DSL)." - [op & {:keys [variadic? ignore-nil?]}] + [op & {:keys [variadic ignore-nil]}] (assert (keyword? op)) (swap! infix-ops conj op) - (when variadic? + (when variadic (swap! op-variadic conj op)) - (when ignore-nil? + (when ignore-nil (swap! op-ignore-nil conj op))) (comment @@ -865,4 +865,10 @@ [:= :bar [:param :quux]]]} {:params {:foo 42 :quux 13} :pretty true})) + ;; while working on the docs + (require '[honey.sql :as sql]) + (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) + (sql/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + (sql/format {:select [:foo/bar] :from [:q-u-u-x]} {:quoted true}) + (sql/format {:select ["foo/bar"] :from [:q-u-u-x]} {:quoted true}) ,) From 1b749c15992ba6629117d207ca500f3fb7dc5b33 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 16:24:19 -0800 Subject: [PATCH 106/254] Overhaul differences document --- README.md | 4 +-- doc/differences-from-1-x.md | 65 +++++++++++++++++++++++++++++-------- test/honeysql/core.cljc | 6 ++++ 3 files changed, 60 insertions(+), 15 deletions(-) diff --git a/README.md b/README.md index e8ab2f2..42e5372 100644 --- a/README.md +++ b/README.md @@ -591,7 +591,7 @@ If your database supports `<=>` as an operator, you can tell HoneySQL about it u (-> (select :a) (where [:<=> :a "foo"]) sql/format) => ["SELECT a WHERE a <=> ?" "foo"] ;; you can declare that an operator is variadic: -(sql/register-op! :<=> :variadic? true) +(sql/register-op! :<=> :variadic true) (-> (select :a) (where [:<=> "food" :a "fool"]) sql/format) => ["SELECT a WHERE ? <=> a <=> ?" "food" "fool"] ``` @@ -599,7 +599,7 @@ If your database supports `<=>` as an operator, you can tell HoneySQL about it u Sometimes you want an operator to ignore `nil` clauses (`:and` and `:or` are declared that way): ```clojure -(sql/register-op! :<=> :ignore-nil? true) +(sql/register-op! :<=> :ignore-nil true) ``` Or perhaps your database supports syntax like `a BETWIXT b AND c`, in which case you can use `register-fn!` to tell HoneySQL about it (again, called before the first call to `honey.sql/format`): diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 6153972..bc437cb 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -10,7 +10,7 @@ The DSL itself -- the data structures that both versions convert to SQL and para HoneySQL 2.x uses the group ID `seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). -In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure is available in `honey.specs` (work in progress). +In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure will be available in `honey.specs` at some point (work in progress). ### HoneySQL 1.x @@ -27,6 +27,8 @@ honeysql/honeysql {:mvn/version "1.0.444"} ... (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) ;;=> ["SELECT * FROM table WHERE id = ?" 1] + (sql/format {:select [:*] :from [:table] :where [:= :id 1]} :quoting :mysql) + ;;=> ["SELECT * FROM `table` WHERE `id` = ?" 1] ``` The namespaces were: @@ -36,6 +38,8 @@ The namespaces were: * `honeysql.types` -- records, protocols, and data readers, * `honeysql.util` -- internal utilities (macros). +Supported Clojure versions: 1.7 and later. + ### HoneySQL 2.x ```clojure @@ -49,6 +53,8 @@ seancorfield/honeysql {:mvn/version "2.x"} ... (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) ;;=> ["SELECT * FROM table WHERE id = ?" 1] + (sql/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) + ;;=> ["SELECT * FROM `table` WHERE `id` = ?" 1] ``` The new namespaces are: @@ -56,15 +62,17 @@ The new namespaces are: * `honey.sql.helpers` -- helper functions to build the DSL, * `honey.specs` -- a description of the DSL using `clojure.spec.alpha`. +Supported Clojure versions: 1.9 and later. + ## API Changes The primary API is just `honey.sql/format`. The `array`, `call`, `inline`, `param`, and `raw` functions have all become standard syntax in the DSL as functions (and their tagged literal equivalents have also gone away because they are no longer needed). Other `honeysql.core` functions that no longer exist include: `build`, `qualify`, and `quote-identifier`. Many other public functions were essentially undocumented (neither mentioned in the README nor in the tests) and also no longer exist. -You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialect!` function (which sets a default dialect for all `format` operations) or by passing the new `:dialect` option to the `format` function. `:ansi` is the default dialect (which will mostly incorporate PostgreSQL usage over time). Other dialects supported are `:mysql` (which has a different quoting strategy and uses a different ranking for the `:set` clause), `:oracle` (which is essentially the `:ansi` dialect but will control other things over time), and `:sqlserver` (which is essentially the `:ansi` dialect but with a different quoting strategy) and . Other dialects and changes may be added over time. +You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialect!` function (which sets a default dialect for all `format` operations) or by passing the new `:dialect` option to the `format` function. `:ansi` is the default dialect (which will mostly incorporate PostgreSQL usage over time). Other dialects supported are `:mysql` (which has a different quoting strategy and uses a different ranking for the `:set` clause), `:oracle` (which is essentially the `:ansi` dialect but will control other things over time), and `:sqlserver` (which is essentially the `:ansi` dialect but with a different quoting strategy). Other dialects and changes may be added over time. -> Note: `:limit` and `:offset` are currently in the default `:ansi` dialect even though they are MySQL-specific. This is temporary as the dialects are being fleshed out. I expect to add `:top` for `:sqlserver` and `:offset` / `:fetch` for `:ansi`, at which point `:limit` / `:offset` will become MySQL-only. +> Note: `:limit` and `:offset` are currently in the default `:ansi` dialect even though they are MySQL-specific. This will change as the dialects are fleshed out. I plan to add `:top` for `:sqlserver` and `:offset` / `:fetch` for `:ansi`, at which point `:limit` / `:offset` will become MySQL-only. ## Option Changes @@ -75,11 +83,36 @@ The `:quoting ` option has superseded by the new dialect machinery and Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. The following options are no longer supported: -* `:namespace-as-table?` -- TODO +* `:allow-dashed-names?` -- if you provide dashed-names in v2, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without); v1 treated names specified as keywords and names specified as strings differently. +* `:allow-namespaced-names?` -- this supported `foo/bar` column names in SQL which I'd like to discourage. +* `:namespace-as-table?` -- this is the default in v2: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. * `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). +* `:return-param-names` -- this was added to v1 back in 2013 without an associated issue or PR so I've no idea what use case this was intended to support. + +> Note: I expect some push back on those first three options and the associated behavior changes. ## DSL Changes +The general intent is that the data structure behind the DSL is unchanged, for the most part. The only deliberate change is the removal of the reader literals (and their associated helper functions) in favor of standardized syntax, e.g., `[:array [1 2 3]]` instead of either `#sql/array [1 2 3]` or `(sql/array [1 2 3])`. + +The following new syntax has been added: + +* `:array` -- used as a function to replace the `sql/array` / `#sql/array` machinery, +* `:between` -- this is now explicit syntax rather than being a special case in expressions, +* `:case` -- this is now explicit syntax, +* `:cast` -- `[:cast expr :type]` => `CAST( expr AS type )`, +* `:composite` -- explicit syntax to produce a comma-separated list of expressions, wrapped in parentheses, +* `:default` -- for `DEFAULT` values (in inserts), +* `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, +* `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. +* `:lift` -- used as a function to prevent interpretation of a Clojure data structure as DSL syntax (e.g., when passing a vector or hash map as a parameter value), +* `:nest` -- used as a function to add an extra level of nesting (parentheses) around an expression, +* `:not` -- this is now explicit syntax, +* `:param` -- used as a function to replace the `sql/param` / `#sql/param` machinery, +* `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the v1 behavior but should be more flexible, since you can now embed `:inline`, `:param`, and `:lift` inside a `:raw` expression. + +> Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). + You can now `SELECT` a function call more easily, using `[[...]]`. This was previously an error -- missing an alias -- but it was a commonly requested change, to avoid using `(sql/call ...)`: ```clojure @@ -89,17 +122,23 @@ You can now `SELECT` a function call more easily, using `[[...]]`. This was prev ``` +On a related note, `sql/call` has been removed because it should never be needed now: `[:foo ...]` should always be treated as a function call, consistently, avoiding the special cases in v1 that necessitated the explicit `sql/call` syntax. + The `:set` clause is dialect-dependent. In `:mysql`, it is ranked just before the `:where` clause. In all other dialects, it is ranked just before the `:from` clause. Accordingly, the `:set0` and `:set1` clauses are no longer supported (because they were workarounds in 1.x for this conflict). -The following new syntax has been added: - -* `:array` -- used as a function to replace the `sql/array` / `#sql/array` machinery, -* `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, -* `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. -* `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the v1 behavior but should be more flexible. - -> Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). - ## Extensibility The protocols and multimethods in 1.x have all gone away. The primary extension point is `honey.sql/register-clause!` which lets you specify the new clause (keyword), the formatter function for it, and the existing clause that it should be ranked before (`format` processes the DSL in clause order). + +You can also register new "functions" that can implement special syntax (such as `:array`, `:inline`, `:raw` etc above) via `honey.sql/register-fn!`. This accepts a "function" name as a keyword and a formatter which will generally be a function of two arguments: the function name (so formatters can be reused across different names) and a vector of the arguments the function should accept. + +And, finally, you can register new operators that will be recognized in expressions via `honey.sql/register-op!`. This accepts an operator name as a keyword and optional named parameters to indicate whether the operator is `:variadic` (the default is strictly binary) and whether it should ignore operands that evaluate to `nil` (via `:ignore-nil`). The latter can make it easier to construct complex expressions programmatically without having to worry about conditionally removing "optional" (`nil`) values. + +## Helpers + +The `honey.sql.helpers` namespace includes a helper function that corresponds to every supported piece of the data DSL understood by HoneySQL (v1 only had a limited set of helper functions). Unlike v1 helpers which sometimes had both a regular helper and a `merge-` helper, v2 helpers will all merge clauses by default (if that makes sense for the underlying DSL): use `:dissoc` if you want to force an overwrite. + +The only helpers that have non-merging behavior are: +* `intersect`, `union`, `union-all`, `except`, and `except-all` which always wrap around their arguments, +* `delete`, `set`, `limit`, `offset`, `for`, and `values` which overwrite, rather than merge, +* `composite` which is a convenience for the `:composite` syntax mentioned above: `(composite :a :b)` is the same as `[:composite :a :b]` which produces `(a, b)`. diff --git a/test/honeysql/core.cljc b/test/honeysql/core.cljc index fcb1541..8a2a144 100644 --- a/test/honeysql/core.cljc +++ b/test/honeysql/core.cljc @@ -68,3 +68,9 @@ base (apply build (apply concat base))) (partition 2 clauses)))) + +(comment + (require '[honeysql.core :as sql]) + (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) + (sql/format {:select [:*] :from [:table] :where [:= :id 1]} :quoting :mysql) + ,) From 68eb5905276ff8f033de7ba4e345a098aeff5c9f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 16:45:18 -0800 Subject: [PATCH 107/254] Add note about nilenso-postgres --- doc/differences-from-1-x.md | 2 ++ 1 file changed, 2 insertions(+) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index bc437cb..91f8728 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -134,6 +134,8 @@ You can also register new "functions" that can implement special syntax (such as And, finally, you can register new operators that will be recognized in expressions via `honey.sql/register-op!`. This accepts an operator name as a keyword and optional named parameters to indicate whether the operator is `:variadic` (the default is strictly binary) and whether it should ignore operands that evaluate to `nil` (via `:ignore-nil`). The latter can make it easier to construct complex expressions programmatically without having to worry about conditionally removing "optional" (`nil`) values. +> Note: because of the changes in the extension machinery between v1 and v2, it is not possible to use the https://github.com/nilenso/honeysql-postgres library with HoneySQL v2 but the goal is to incorporate all of the syntax from that library into the core of HoneySQL. + ## Helpers The `honey.sql.helpers` namespace includes a helper function that corresponds to every supported piece of the data DSL understood by HoneySQL (v1 only had a limited set of helper functions). Unlike v1 helpers which sometimes had both a regular helper and a `merge-` helper, v2 helpers will all merge clauses by default (if that makes sense for the underlying DSL): use `:dissoc` if you want to force an overwrite. From 4cbeb170ddf4ba0d7238c43b092ffb0a33062474 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 1 Feb 2021 16:45:35 -0800 Subject: [PATCH 108/254] Ensure no dependence on vector (vs sequence) --- src/honey/sql.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1f8e0f8..4e51f5a 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -638,7 +638,7 @@ (if (sequential? s) (let [[sqls params] (reduce (fn [[sqls params] s] - (if (vector? s) + (if (coll? s) (let [[sql & params'] (format-expr s)] [(conj sqls sql) (into params params')]) From 25acc53b246cd7db96ae5f158f3a6c37ff45e995 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 2 Feb 2021 12:12:01 -0800 Subject: [PATCH 109/254] Bump cljs-test-runner to get more recent cljs So that `(symbol :kw)` works (although I decided to use an explcit call to `name` instead. --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index a5ab324..f511376 100644 --- a/deps.edn +++ b/deps.edn @@ -13,7 +13,7 @@ :main-opts ["-m" "cognitect.test-runner" ;"-d" "target/test-doc-blocks/test" "-d" "test"]} - :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.7.0"}} + :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.8.0"}} :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} From 80c137949e4783fc12b0753e5da2ea3a8ec14d46 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 2 Feb 2021 12:25:26 -0800 Subject: [PATCH 110/254] Initial Getting Started/Extending HoneySQL docs --- doc/cljdoc.edn | 8 +-- doc/extending-honeysql.md | 99 ++++++++++++++++++++++++++++++ doc/getting-started.md | 124 +++++++++++++++++++++++++++++++++++++- src/honey/sql.cljc | 116 +++++++++++++++++++++++++---------- 4 files changed, 307 insertions(+), 40 deletions(-) create mode 100644 doc/extending-honeysql.md diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn index b348933..9691209 100644 --- a/doc/cljdoc.edn +++ b/doc/cljdoc.edn @@ -1,11 +1,5 @@ {:cljdoc.doc/tree [["Readme" {:file "README.md"}] ["Changes" {:file "CHANGELOG.md"}] ["Getting Started" {:file "doc/getting-started.md"} - #_["Friendly SQL Functions" {:file "doc/friendly-sql-functions.md"}] - #_["Tips & Tricks" {:file "doc/tips-and-tricks.md"}] - #_["Result Set Builders" {:file "doc/result-set-builders.md"}] - #_["Prepared Statements" {:file "doc/prepared-statements.md"}] - #_["Transactions" {:file "doc/transactions.md"}]] - #_["All The Options" {:file "doc/all-the-options.md"}] - #_["datafy, nav, and :schema" {:file "doc/datafy-nav-and-schema.md"}] + ["Extending HoneySQL" {:file "doc/extending-honeysql.md"}]] ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} diff --git a/doc/extending-honeysql.md b/doc/extending-honeysql.md new file mode 100644 index 0000000..6732325 --- /dev/null +++ b/doc/extending-honeysql.md @@ -0,0 +1,99 @@ +# Extending HoneySQL + +Out of the box, HoneySQL supports most standard ANSI SQL clauses +and expressions but where it doesn't support something you need +you can add new clauses, new operators, and new "functions" (or +"special syntax"). + +There are three extension points in `honey.sql` that let you +register formatters or behavior corresponding to clauses, +operators, and functions. + +Built in clauses include: `:select`, `:from`, `:where` and +many more. Built in operators include: `:=`, `:+`, `:mod`. +Built in functions (special syntax) include: `:array`, `:case`, +`:cast`, `:inline`, `:raw` and many more. + +## Registering a New Clause Formatter + +## Registering a New Operator + +`honey.sql/register-op!` accepts a keyword (or a symbol) that +should be treated as a new infix operator. + +By default, operators are treated as strictly binary -- +accepting just two arguments -- and an exception will be +thrown if they are provided less than two or more than +two arguments. You can optionally specify that an operator +can take any number of arguments with `:variadic true`: + +```clojure +(sql/register-op! :<=> :variadic true) +;; and then use the new operator: +(sql/format {:select [:*], :from [:table], :where [:<=> 13 :x 42]}) +;; will produce: +;;=> ["SELECT * FROM table WHERE ? <=> x <=> ?" 13 42] +``` + +If you are building expressions programmatically, you +may want your new operator to ignore "empty" expressions, +i.e., where your expression-building code might produce +`nil`. The built-in operators `:and` and `:or` ignore +such `nil` expressions. You can specify `:ignore-nil true` +to achieve that: + +```clojure +(sql/register-op! :<=> :variadic true :ignore-nil true) +;; and then use the new operator: +(sql/format {:select [:*], :from [:table], :where [:<=> nil :x 42]}) +;; will produce: +;;=> ["SELECT * FROM table WHERE x <=> ?" 42] +``` + +## Registering a New Function (Special Syntax) + +`honey.sql/register-fn!` accepts a keyword (or a symbol) +that should be treated as new syntax (as a function call), +and a "formatter". The formatter can either be a function +of two arguments or a previously registered "function" (so +that you can easily reuse formatters). + +The formatter will be called with: +* The function name (always as a keyword), +* The sequence of arguments provided. + +For example: + +```clojure +(sql/register-fn! :foo (fn [f args] ..)) + +(sql/format {:select [:*], :from [:table], :where [:foo 1 2 3]}) +``` + +Your formatter function will be called with `:foo` and `(1 2 3)`. +It should return a vector containing a SQL string followed by +any parameters: + +```clojure +(sql/register-fn! :foo (fn [f args] ["FOO(?)" (first args)])) + +(sql/format {:select [:*], :from [:table], :where [:foo 1 2 3]}) +;; produces: +;;=> ["SELECT * FROM table WHERE FOO(?)" 1] +``` + +In practice, it is likely that your formatter would call +`sql/sql-kw` on the function name to produce a SQL representation +of it and would call `sql/format-expr` on each argument: + +```clojure +(defn- foo-formatter [f [x]] + (let [[sql & params] (sql/format-expr x)] + (into [(str (sql/sql-kw f) "(" sql ")")] params))) + +(sql/register-fn! :foo foo-formatter) + +(sql/format {:select [:*], :from [:table], :where [:foo [:+ :a 1]]}) +;; produces: +;;=> ["SELECT * FROM table WHERE FOO(a + ?)" 1] +``` diff --git a/doc/getting-started.md b/doc/getting-started.md index 9fba60b..8941caa 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -1,3 +1,125 @@ # Getting Started with HoneySQL -tbd +HoneySQL lets you build complex SQL statements by constructing +and composing Clojure data structures and then formatting that +data to a SQL statement (string) and any parameters it needs. + +## Installation + +For the Clojure CLI, add the following dependency to your `deps.edn` file: + +```clojure + seancorfield/honeysql {:mvn/version "2.0.0-alpha1"} +``` + +For Leiningen, add the following dependency to your `project.clj` file: + +```clojure + [seancorfield/honeysql "2.0.0-alpha1"] +``` + +> Note: 2.0.0-alpha1 will be released shortly! + +HoneySQL produces SQL statements but does not execute them. +To execute SQL statements, you will also need a JDBC wrapper like +[`seancorfield/next.jdbc`](https://github.com/seancorfield/next-jdbc) and a JDBC driver for the database you use. + +## Basic Concepts + +SQL statements are represented as hash maps, with keys that +represent clauses in SQL. SQL expressions are generally +represented as vectors, where the first element identifies +the function or operator and the remaining elements are the +arguments or operands. + +`honey.sql/format` takes a hash map representing a SQL +statement and produces a vector, suitable for use with +`next.jdbc` or `clojure.java.jdbc`, that has the generated +SQL string as the first element followed by any parameter +values identified in the SQL expressions: + +```clojure +(ns my.example + (:require [honey.sql :as sql])) + +(sql/format {:select [:*], :from [:table], :where [:= :id 1]}) +;; produces: +;;=> ["SELECT * FROM table WHERE id = ?" 1] +``` + +Any values found in the data structure, that are not keywords +or symbols, are treated as positional parameters and replaced +by `?` in the SQL string and lifted out into the vector that +is returned from `format`. + +Nearly all clauses expect a vector as their value, containing +either a list of SQL entities or the representation of a SQL +expression. + +A SQL entity can be a simple keyword (or symbol) or a pair +that represents a SQL entity and its alias: + +```clojure +(sql/format {:select [:t.id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) +;; produces: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] +``` + +The `FROM` clause now has a pair that identifies the SQL entity +`table` and its alias `t`. Columns can be identified either by +their qualified name (as in `:t.id`) or their unqualified name +(as in `:name`). The `SELECT` clause here identifies two SQL +entities: `t.id` and `name` with the latter aliased to `item`. + +Symbols can also be used, but you need to quote them to +avoid evaluation: + +```clojure +(sql/format '{select [t.id [name item]], from [[table t]], where [= id 1]}) +;; also produces: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] +``` + +If you wish, you can specify SQL entities as namespace-qualified +keywords (or symbols) and the namespace portion will treated as +the table name, i.e., `:foo/bar` instead of `:foo.bar`: + +```clojure +(sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) +;; and +(sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]}) +;; both produce: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] +``` + +In addition to the hash map (and vectors) approach of building +SQL queries with raw Clojure data structures, a namespace full +of helper functions is also available. These functions are +generally variadic and threadable: + +```clojure +(ns my.example + (:require [honey.sql :as sql] + [honey.sql.helpers :refer [select from where]])) + +(-> (select :t/id [:name :item]) + (from [:table :t]) + (where [:= :id 1]) + (sql/format)) +;; produces: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] +``` + +In addition to being variadic -- which often lets you omit one +level of `[`..`]` -- the helper functions merge clauses, which +can make it easier to build queries programmatically: + +```clojure +(-> (select :t/id) + (from [:table :t]) + (where [:= :id 1]) + (select [:name :item]) + (sql/format)) +;; produces: +;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] +``` diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4e51f5a..05c0997 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -107,11 +107,33 @@ "Given a keyword, return a SQL representation of it as a string. A `:kebab-case` keyword becomes a `KEBAB CASE` (uppercase) string - with hyphens replaced by spaces, e.g., `:insert-into` => `INSERT INTO`." + with hyphens replaced by spaces, e.g., `:insert-into` => `INSERT INTO`. + + Any namespace qualifier is ignored." [k] (-> k (name) (upper-case) (as-> s (if (= "-" s) s (str/replace s "-" " "))))) +(defn- sym->kw + "Given a symbol, produce a keyword, retaining the namespace + qualifier, if any." + [s] + (if (symbol? s) + (if-let [n (namespace s)] + (keyword n (name s)) + (keyword (name s))) + s)) + +(defn- kw->sym + "Given a keyword, produce a symbol, retaining the namespace + qualifier, if any." + [k] + (if (keyword? k) + (if-let [n (namespace k)] + (symbol n (name k)) + (symbol (name k))) + k)) + (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) @@ -493,13 +515,13 @@ (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] (if-let [xs (or (k statement-map) - (let [s (symbol (name k))] + (let [s (kw->sym k)] (get statement-map s)))] (let [formatter (k @clause-format) [sql' & params'] (formatter k xs)] [(conj sql sql') (if params' (into params params') params) - (dissoc leftover k (symbol (name k)))]) + (dissoc leftover k (kw->sym k))]) [sql params leftover])) [[] [] statement-map] *clause-order*)] @@ -638,7 +660,7 @@ (if (sequential? s) (let [[sqls params] (reduce (fn [[sqls params] s] - (if (coll? s) + (if (sequential? s) (let [[sql & params'] (format-expr s)] [(conj sqls sql) (into params params')]) @@ -663,10 +685,7 @@ (format-dsl expr (assoc opts :nested true)) (sequential? expr) - (let [op (first expr) - ;; normalize symbols to keywords here -- makes the subsequent - ;; logic easier since we use op to lookup things in hash maps: - op (if (symbol? op) (keyword (name op)) op)] + (let [op (sym->kw (first expr))] (if (keyword? op) (cond (contains? @infix-ops op) (if (contains? @op-variadic op) ; no aliases here, no special semantics @@ -791,16 +810,18 @@ only clause so far where that would matter is `:set` which differs in MySQL." [clause formatter before] - (assert (keyword? clause)) - (let [f (if (keyword? formatter) - (get @clause-format formatter) - formatter)] - (when-not (and f (fn? f)) - (throw (ex-info "The formatter must be a function or existing clause" - {:type (type formatter)}))) - (swap! base-clause-order add-clause-before clause before) - (swap! current-clause-order add-clause-before clause before) - (swap! clause-format assoc clause f))) + (let [clause (sym->kw clause)] + (assert (keyword? clause)) + (let [k (sym->kw formatter) + f (if (keyword? k) + (get @clause-format k) + formatter)] + (when-not (and f (fn? f)) + (throw (ex-info "The formatter must be a function or existing clause" + {:type (type formatter)}))) + (swap! base-clause-order add-clause-before clause before) + (swap! current-clause-order add-clause-before clause before) + (swap! clause-format assoc clause f)))) (defn register-fn! "Register a new function (as special syntax). The `formatter` is either @@ -810,26 +831,29 @@ of the function (as a keyword) and a sequence of the arguments from the DSL." [function formatter] - (assert (keyword? function)) - (let [f (if (keyword? formatter) - (get @special-syntax formatter) - formatter)] - (when-not (and f (fn? f)) - (throw (ex-info "The formatter must be a function or existing fn name" - {:type (type formatter)}))) - (swap! special-syntax assoc function f))) + (let [function (sym->kw function)] + (assert (keyword? function)) + (let [k (sym->kw formatter) + f (if (keyword? k) + (get @special-syntax k) + formatter)] + (when-not (and f (fn? f)) + (throw (ex-info "The formatter must be a function or existing fn name" + {:type (type formatter)}))) + (swap! special-syntax assoc function f)))) (defn register-op! "Register a new infix operator. Operators can be defined to be variadic (the default is that they are binary) and may choose to ignore `nil` arguments (this can make it easier to programmatically construct the DSL)." [op & {:keys [variadic ignore-nil]}] - (assert (keyword? op)) - (swap! infix-ops conj op) - (when variadic - (swap! op-variadic conj op)) - (when ignore-nil - (swap! op-ignore-nil conj op))) + (let [op (sym->kw op)] + (assert (keyword? op)) + (swap! infix-ops conj op) + (when variadic + (swap! op-variadic conj op)) + (when ignore-nil + (swap! op-ignore-nil conj op)))) (comment (format {:truncate :foo}) @@ -868,7 +892,35 @@ ;; while working on the docs (require '[honey.sql :as sql]) (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) + (sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) + (sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]}) + (sql/format '{select * from table where (= id 1)}) + (require '[honey.sql.helpers :refer [select from where]]) + (-> (select :t/id [:name :item]) + (from [:table :t]) + (where [:= :id 1]) + (sql/format)) + (-> (select :t/id) + (from [:table :t]) + (where [:= :id 1]) + (select [:name :item]) + (sql/format)) (sql/format {:select [:*] :from [:table] :where [:= :id 1]} {:dialect :mysql}) (sql/format {:select [:foo/bar] :from [:q-u-u-x]} {:quoted true}) (sql/format {:select ["foo/bar"] :from [:q-u-u-x]} {:quoted true}) + (sql/format-expr [:primary-key]) + (sql/register-op! 'y) + (sql/format {:where '[y 2 3]}) + (sql/register-op! :<=> :variadic true :ignore-nil true) + ;; and then use the new operator: + (sql/format {:select [:*], :from [:table], :where [:<=> nil :x 42]}) + (sql/register-fn! :foo (fn [f args] ["FOO(?)" (first args)])) + (sql/format {:select [:*], :from [:table], :where [:foo 1 2 3]}) + (defn- foo-formatter [f [x]] + (let [[sql & params] (sql/format-expr x)] + (into [(str (sql/sql-kw f) "(" sql ")")] params))) + + (sql/register-fn! :foo foo-formatter) + + (sql/format {:select [:*], :from [:table], :where [:foo [:+ :a 1]]}) ,) From ea0bfbabc1e779378bb08d4b46601e086ff978c9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 2 Feb 2021 14:50:12 -0800 Subject: [PATCH 111/254] Outline of docs for clauses, operators, and special syntax --- doc/clause-reference.md | 38 +++++++++++++++++++++++++ doc/cljdoc.edn | 14 ++++++---- doc/extending-honeysql.md | 26 +++++++++++++++++- doc/operator-reference.md | 58 +++++++++++++++++++++++++++++++++++++++ doc/special-syntax.md | 19 +++++++++++++ src/honey/sql.cljc | 5 +++- 6 files changed, 153 insertions(+), 7 deletions(-) create mode 100644 doc/clause-reference.md create mode 100644 doc/operator-reference.md create mode 100644 doc/special-syntax.md diff --git a/doc/clause-reference.md b/doc/clause-reference.md new file mode 100644 index 0000000..c09efc7 --- /dev/null +++ b/doc/clause-reference.md @@ -0,0 +1,38 @@ +# SQL Clauses Supported + +This section lists all the SQL clauses that HoneySQL +supports out of the box, in the order that they are +processed for formatting. + +Clauses can be specified as keywords or symbols. Use +`-` in the clause name where the formatted SQL would have +a space (e.g., `:left-join` is formatted as `LEFT JOIN`). + +Except as noted, these clauses apply to all the SQL +dialects that HoneySQL supports. + +## nest +## with, with-recursive +## intersect, union, union-all, except, except-all +## select, select-distinct +## insert-into +## update +## delete, delete-from +## truncate +## columns +## set (ANSI) +## from +## using +## join, left-join, right-join, inner-join, outer-join, full-join +## cross-join +## set (MySQL) +## where +## group-by +## having +## order-by +## limit, offset (MySQL) +## for +## lock (MySQL) +## values +## on-conflict, on-constraint, do-nothing, do-update-set +## returning \ No newline at end of file diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn index 9691209..0326f74 100644 --- a/doc/cljdoc.edn +++ b/doc/cljdoc.edn @@ -1,5 +1,9 @@ -{:cljdoc.doc/tree [["Readme" {:file "README.md"}] - ["Changes" {:file "CHANGELOG.md"}] - ["Getting Started" {:file "doc/getting-started.md"} - ["Extending HoneySQL" {:file "doc/extending-honeysql.md"}]] - ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} +{:cljdoc.doc/tree + [["Readme" {:file "README.md"}] + ["Changes" {:file "CHANGELOG.md"}] + ["Getting Started" {:file "doc/getting-started.md"} + ["SQL Clause Reference" {:file "doc/clause-reference.md"}] + ["SQL Operator Reference" {:file "doc/operator-reference.md"}] + ["SQL 'Special Syntax'" {:file "doc/special-syntax.md"}] + ["Extending HoneySQL" {:file "doc/extending-honeysql.md"}]] + ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} diff --git a/doc/extending-honeysql.md b/doc/extending-honeysql.md index 6732325..3894636 100644 --- a/doc/extending-honeysql.md +++ b/doc/extending-honeysql.md @@ -16,6 +16,30 @@ Built in functions (special syntax) include: `:array`, `:case`, ## Registering a New Clause Formatter +`honey.sql/register-clause!` accepts a keyword (or a symbol) +that should be treated as a new clause in a SQL statement, +a "formatter", and a keyword (or a symbol) that identifies +an existing clause that this new one should be ordered before. + +The formatter can either be a function +of two arguments or a previously registered clause (so +that you can easily reuse formatters). + +The formatter function will be called with: +* The function name (always as a keyword), +* The sequence of arguments provided. + +The third argument to `register-clause!` allows you to +insert your new clause formatter so that clauses are +formatted in the correct order for your SQL dialect. +For example, `:select` comes before `:from` which comes +before `:where`. This is the most implementation-specific +part of extending HoneySQL because you'll need to look at +the (private) Var `default-clause-order` in `honey.sql` +for guidance. _[I plan to add a section in the documentation +somewhere that lists built-in clauses in order which this +can link to...]_ + ## Registering a New Operator `honey.sql/register-op!` accepts a keyword (or a symbol) that @@ -58,7 +82,7 @@ and a "formatter". The formatter can either be a function of two arguments or a previously registered "function" (so that you can easily reuse formatters). -The formatter will be called with: +The formatter function will be called with: * The function name (always as a keyword), * The sequence of arguments provided. diff --git a/doc/operator-reference.md b/doc/operator-reference.md new file mode 100644 index 0000000..36e4a58 --- /dev/null +++ b/doc/operator-reference.md @@ -0,0 +1,58 @@ +# SQL Operators Supported + +This section lists the operators that HoneySQL supports +out of the box. There is no operator precedence assumed +because SQL expressions are represented in prefix form, +just like Clojure expressions. + +Operators can be specified as keywords or symbols. Use +`-` in the operator where the formatted SQL would have +a space (e.g., `:not-like` is formatted as `NOT LIKE`). + +## and, or + +Boolean operators. May take any number of expressions +as arguments. `nil` expressions are ignored which can +make it easier to programmatically build conditional +expressions (since an expression that should be omitted +can simply evaluate to `nil` instead). + +```clojure +{... + :where [:and [:= :type "match"] + (when need-status [:in :status [1 5]])] + ...} +;; if need-status is truthy: +;;=> ["...WHERE (type = ?) AND (status IN (?, ?))..." "match" 1 5] +;; or, if need-status is falsey: +;;=> ["...WHERE (type = ?)..." "match"] +{... + :where [:or [:= :id 42] [:= :type "match"]] + ...} +;;=> ["...WHERE (id = ?) OR (type = ?)..." 42 "match"] +``` + +## = <> < > <= >= + +Binary comparison operators. These expect exactly +two arguments. + +The following aliases are also supported: +* `is` -- an alias for `=` +* `is-not`, `not=`, `!=` -- aliases for `<>` + +## mod, xor, + - * / % | & ^ + +Mathematical and bitwise operators. `+` and `*` are +variadic; the rest are strictly binary operators. + +## like, not like, ilike, not ilike, regexp + +Pattern matching binary operators. `regex` is accepted +as an alias for `regexp`. + +`similar-to` and `not-similar-to` are also supported. + +## || + +Variadic string concatenation operator. diff --git a/doc/special-syntax.md b/doc/special-syntax.md new file mode 100644 index 0000000..b52600a --- /dev/null +++ b/doc/special-syntax.md @@ -0,0 +1,19 @@ +# SQL Special Syntax + +This section lists the function-like expressions that +HoneySQL supports out of the box which are formatted +as special syntactic forms. + +## array +## between +## case +## cast +## composite +## default +## inline +## interval +## lift +## nest +## not +## param +## raw diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 05c0997..ac322e3 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -810,7 +810,8 @@ only clause so far where that would matter is `:set` which differs in MySQL." [clause formatter before] - (let [clause (sym->kw clause)] + (let [clause (sym->kw clause) + before (sym->kw before)] (assert (keyword? clause)) (let [k (sym->kw formatter) f (if (keyword? k) @@ -891,6 +892,8 @@ :pretty true})) ;; while working on the docs (require '[honey.sql :as sql]) + (sql/format {:where [:and [:= :id 42] [:= :type "match"]]}) + (sql/format {:where [:and [:= :type "match"] (when false [:in :status [1 5]])]}) (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) (sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) (sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]}) From 1d2b8e8203d0f103c9be95986a421897581791ce Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 2 Feb 2021 16:43:09 -0800 Subject: [PATCH 112/254] Document special syntax --- doc/extending-honeysql.md | 2 +- doc/special-syntax.md | 155 ++++++++++++++++++++++++++++++++++++++ src/honey/sql.cljc | 4 +- 3 files changed, 159 insertions(+), 2 deletions(-) diff --git a/doc/extending-honeysql.md b/doc/extending-honeysql.md index 3894636..69dafe9 100644 --- a/doc/extending-honeysql.md +++ b/doc/extending-honeysql.md @@ -26,7 +26,7 @@ of two arguments or a previously registered clause (so that you can easily reuse formatters). The formatter function will be called with: -* The function name (always as a keyword), +* The clause name (always as a keyword), * The sequence of arguments provided. The third argument to `register-clause!` allows you to diff --git a/doc/special-syntax.md b/doc/special-syntax.md index b52600a..d3be25a 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -5,15 +5,170 @@ HoneySQL supports out of the box which are formatted as special syntactic forms. ## array + +Accepts a single argument, which is expected to evaluate to +a sequence, and produces `ARRAY[?, ?, ..]` for the elements +of that sequence (as SQL parameters): + +```clojure +(sql/format-expr [:array (range 5)]) +;;=> ["ARRAY[?, ?, ?, ?, ?]" 0 1 2 3 4] +``` + ## between + +Accepts three arguments: an expression, a lower bound, and +an upper bound: + +```clojure +(sql/format-expr [:between :id 1 100]) +;;=> ["id BETWEEN ? AND ?" 1 100] +``` + ## case + +A SQL CASE expression. Expects an even number of arguments: +alternating condition and result expressions. A condition +may be `:else` (or `'else`) to produce `ELSE`, otherwise +`WHEN THEN ` will be produced: + +```clojure +(sql/format-expr [:case [:< :a 10] "small" [:> :a 100] "big" :else "medium"]) +;;=> ["CASE WHEN a < ? THEN ? WHEN a > ? THEN ? ELSE ? END" +;; 10 "small" 100 "big" "medium"] +``` + ## cast + +A SQL CAST expression. Expects an expression and something +that produces a SQL type: + +```clojure +(sql/format-expr [:cast :a :int]) +;;=> ["CAST(a AS int)"] +``` + ## composite + +Accepts any number of expressions and produces a composite +expression (comma-separated, wrapped in parentheses): + +```clojure +(sql/format-expr [:composite :a :b "red" [:+ :x 1]]) +;;=> ["(a, b, ?, x + ?)" "red" 1] +``` + ## default + +Takes no arguments and produces the SQL keyword `DEFAULT`. + +_[I expect this to be expanded for PostgreSQL]_ + ## inline + +Accepts a single argument and tries to render it as a +SQL value directly in the formatted SQL string rather +than turning it into a positional parameter: +* `nil` becomes `NULL` +* keywords and symbols become upper case entities (with `-` replaced by space) +* strings become inline SQL strings (with single quotes) +* a sequence has each element formatted inline and then joined with spaces +* all other values are just rendered via Clojure's `str` function + +```clojure +(sql/format {:where [:= :x [:inline "foo"]]}) +;;=> ["WHERE x = 'foo'"] +``` + ## interval + +Accepts two arguments: an expression and a keyword (or a symbol) +that represents a time unit. Produces an `INTERVAL` expression: + +```clojure +(sql/format-expr [:date_add [:now] [:interval 30 :days]]) +;;=> ["DATE_ADD(NOW(), INTERVAL ? DAYS)" 30] +``` + ## lift + +Used to wrap a Clojure value that should be passed as a +SQL parameter but would otherwise be treated as a SQL +expression or statement, i.e., a sequence or hash map. +This can be useful when dealing with JSON types: + +```clojure +(sql/format {:where [:= :json-col [:lift {:a 1 :b "two"}]]}) +;;=> ["WHERE json_col = ?" {:a 1 :b "two"}] +``` + ## nest + +Used to wrap an expression when you want an extra +level of parentheses around it: + +```clojure +(sql/format {:where [:= :x 42]}) +;;=> ["WHERE x = ?" 42] +(sql/format {:where [:nest [:= :x 42]]}) +;;=> ["WHERE (x = ?)" 42] +``` + +`nest` is also supported as a SQL clause for the same reason. + ## not + +Accepts a single expression and formats it with `NOT` +in front of it: + +```clojure +(sql/format-expr [:not nil]) +;;=> ["NOT NULL"] +(sql/format-expr [:not [:= :x 42]]) +;;=> ["NOT x = ?" 42] +``` + ## param + +Used to identify a named parameter in a SQL expression +as an alternative to a keyword (or a symbol) that begins +with `?`: + +```clojure +(sql/format {:where [:= :x :?foo]} {:params {:foo 42}}) +;;=> ["WHERE x = ?" 42] +(sql/format {:where [:= :x [:param :foo]]} {:params {:foo 42}}) +;;=> ["WHERE x = ?" 42] +``` + ## raw + +Accepts a single argument and renders it as literal SQL +in the formatted string: + +```clojure +(sql/format {:select [:a [[:raw "@var := foo"]]]}) +;;=> ["SELECT a, @var := foo"] +``` + +If the argument is a sequence of expressions, they +will each be rendered literally and joined together +(with no spaces): + +```clojure +(sql/format {:select [:a [[:raw ["@var" " := " "foo"]]]]}) +;;=> ["SELECT a, @var := foo"] +``` + +When a sequence of expressions is supplied, any +subexpressions that are, in turn, sequences will be +formatted as regular SQL expressions and that SQL +will be joined into the result, along with any +parameters from them: + +```clojure +(sql/format {:select [:a [[:raw ["@var := " [:inline "foo"]]]]]}) +;;=> ["SELECT a, @var := 'foo'"] +(sql/format {:select [:a [[:raw ["@var := " ["foo"]]]]]}) +;;=> ["SELECT a, @var := ?" "foo"] +``` diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index ac322e3..fb1ff2c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -608,7 +608,8 @@ (let [[sqlc & paramsc] (when-not (= :else condition) (format-expr condition)) [sqlv & paramsv] (format-expr value)] - [(if (= :else condition) + [(if (or (= :else condition) + (= 'else condition)) (conj sqls (sql-kw :else) sqlv) (conj sqls (sql-kw :when) sqlc (sql-kw :then) sqlv)) (-> params (into paramsc) (into paramsv))])) @@ -892,6 +893,7 @@ :pretty true})) ;; while working on the docs (require '[honey.sql :as sql]) + (sql/format-expr [:array (range 5)]) (sql/format {:where [:and [:= :id 42] [:= :type "match"]]}) (sql/format {:where [:and [:= :type "match"] (when false [:in :status [1 5]])]}) (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) From d71e1149a81d40308462e9d80b485728976b3bb2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 3 Feb 2021 10:59:08 -0800 Subject: [PATCH 113/254] Ignore LSP folder --- .gitignore | 1 + 1 file changed, 1 insertion(+) diff --git a/.gitignore b/.gitignore index 409bedf..5ec5cfd 100644 --- a/.gitignore +++ b/.gitignore @@ -11,6 +11,7 @@ .cpcache .clj-kondo/.cache .eastwood +.lsp .nrepl-port /.rebel_readline_history /.socket-repl-port From c00fbffe30398ea70be6c36e277e3df9ad265902 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Feb 2021 09:00:46 -0800 Subject: [PATCH 114/254] Document with / CTE Change the implementation to support just a pair instead of the legacy, weird sequence of one pair. --- doc/clause-reference.md | 47 ++++++++++++++++++++++++++++++++++++++++ doc/getting-started.md | 2 +- src/honey/sql.cljc | 33 +++++++++++++++------------- test/honey/sql_test.cljc | 14 ++++++++++++ 4 files changed, 80 insertions(+), 16 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index c09efc7..9ef0478 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -12,7 +12,54 @@ Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. ## nest + +This is pseudo-syntax that lets you wrap a substatement +in an extra level of parentheses. It should rarely be +needed and it is mostly present to provide the same +functionality for clauses that `[:nest ..]` provides +for expressions. + ## with, with-recursive + +These provide CTE support for SQL Server. The argument to +`:with` (or `:with-recursive`) is a pair of +a result set name (or description) and a basic SQL statement. +The result set can either be a SQL entity (a simple name) +or a pair of a SQL entity and a set of column names. + +```clojure +user=> (sql/format '{with (stuff {select (:*) from (foo)}) + select (id,name) + from (stuff) + where (= status 0)}) +["WITH stuff AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0] +``` + +You can specify a list of columns for the CTE like this: + +```clojure +user=> (sql/format {:with [[:stuff {:columns [:id :name]}] + {:select [:*] :from [:foo]}] + :select [:id :name] + :from [:stuff] + :where [:= :status 0]}) +["WITH stuff (id, name) AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0] +``` + +You can use a `VALUES` clause in the CTE: + +```clojure +user=> (sql/format {:with [[:stuff {:columns [:id :name]}] + {:values [[1 "Sean"] [2 "Jay"]]}] + :select [:id :name] + :from [:stuff]}) +["WITH stuff (id, name) AS (VALUES (?, ?), (?, ?)) SELECT id, name FROM stuff" 1 "Sean" 2 "Jay"] +``` + +`:with-recursive` follows the same rules as `:with` and produces `WITH RECURSIVE` instead of just `WITH`. + +> Note: HoneySQL 0.6.2 introduced support for CTEs a long time ago and it expected the pair (of result set and query) to be wrapped in a sequence, even though you can only have a single CTE. For backward compatibility, HoneySQL 2.0 accepts that format but it should be considered deprecated. + ## intersect, union, union-all, except, except-all ## select, select-distinct ## insert-into diff --git a/doc/getting-started.md b/doc/getting-started.md index 8941caa..e8b986e 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -47,7 +47,7 @@ values identified in the SQL expressions: ;;=> ["SELECT * FROM table WHERE id = ?" 1] ``` -Any values found in the data structure, that are not keywords +By default, any values found in the data structure, that are not keywords or symbols, are treated as positional parameters and replaced by `?` in the SQL string and lifted out into the vector that is returned from `format`. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index fb1ff2c..7754021 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -278,21 +278,24 @@ [(format-entity x)])) (defn- format-with [k xs] - ;; TODO: a sequence of pairs -- X AS expr -- where X is either [entity expr] - ;; or just entity, as far as I can tell... - (let [[sqls params] - (reduce (fn [[sql params] [sql' & params']] - [(conj sql sql') (if params' (into params params') params)]) - [[] []] - (map (fn [[x expr]] - (let [[sql & params] (format-with-part x) - [sql' & params'] (format-dsl expr)] - ;; according to docs, CTE should _always_ be wrapped: - (cond-> [(str sql " AS " (str "(" sql' ")"))] - params (into params) - params' (into params')))) - xs))] - (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) + ;; 1.x and earlier required a sequence of pairs -- X AS expr -- where + ;; X is either [entity expr] or just entity; but a CTE can only contain + ;; one result set definition so 2.x allows this to be just a pair instead + (let [[result-set query] + (case (count xs) + 1 (if (= 2 (count (first xs))) + (first xs) + (throw (ex-info (str k " expects a sequence with just a single pair") + {:elements (count xs)}))) + 2 xs + (throw (ex-info (str k " expects a pair (result set, query)") + {:elements (count xs)}))) + [sql & params] (format-with-part result-set) + [sql' & params'] (format-dsl query)] + ;; according to docs, CTE should _always_ be wrapped: + (cond-> [(str (sql-kw k) " " sql " AS " (str "(" sql' ")"))] + params (into params) + params' (into params')))) (defn- format-selector [k xs] (format-selects k [xs])) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 714f775..ccb0cb2 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -97,6 +97,7 @@ (format {:select [:vals.a] :from [[{:values [[1 2 3]]} [:vals {:columns [:a :b :c]}]]]})))) (deftest test-cte + ;; 1.x and earlier with the extra sequence wrapping: (is (= (format {:with [[:query {:select [:foo] :from [:bar]}]]}) ["WITH query AS (SELECT foo FROM bar)"])) (is (= (format {:with-recursive [[:query {:select [:foo] :from [:bar]}]]}) @@ -108,6 +109,19 @@ {:values [[1 2] [4 5 6]]}]] :select [:*] :from [:static]}) + ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6])) + ;; 2.x should allow just a pair: + (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]]}]}) + ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, NULL))" 1 2 3 4 5])) + (is (= (format + {:with [[:static {:columns [:a :b :c]}] + {:values [[1 2] [4 5 6]]}] + :select [:*] + :from [:static]}) ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6]))) (deftest insert-into From bb16567d507e0b5cbae2193eedd7346d7d1e9288 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 03:40:29 -0800 Subject: [PATCH 115/254] Document more clauses --- doc/clause-reference.md | 150 ++++++++++++++++++++++++++++++++++++- src/honey/sql/helpers.cljc | 4 +- 2 files changed, 151 insertions(+), 3 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 9ef0478..3452ccf 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -61,25 +61,173 @@ user=> (sql/format {:with [[:stuff {:columns [:id :name]}] > Note: HoneySQL 0.6.2 introduced support for CTEs a long time ago and it expected the pair (of result set and query) to be wrapped in a sequence, even though you can only have a single CTE. For backward compatibility, HoneySQL 2.0 accepts that format but it should be considered deprecated. ## intersect, union, union-all, except, except-all + +These all expect a sequence of SQL clauses, those clauses +will be wrapped in parentheses, and the SQL keyword interspersed +between those clauses. + +```clojure +user=> (sql/format '{union [{select (id,status) from (table-a)} + {select (id,(event status) from (table-b))}]}) +["(SELECT id, status FROM table_a) UNION (SELECT id, event AS status, from, table_b)"] +``` + ## select, select-distinct + +`:select` expects a sequence of SQL entities (column names +or expressions). Any of the SQL entities can be a pair of entity and alias. If you are selecting an expression, you would most +often provide an alias for the expression, but it can be omitted +as in the following: + +```clojure +user=> (sql/format '{select (id, ((* cost 2)), (event status)) + from (table)}) +["SELECT id, cost * ?, event AS status FROM table" 2] +``` + +With an alias on the expression: + +```clojure +user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]] + :from [:table]}) +["SELECT id, cost * ? AS total, event AS status FROM table" 2] +``` + +`:select-distinct` works the same way but produces `SELECT DISTINCT`. + ## insert-into + +There are two use cases with `:insert-into`. The first case +takes just a simple SQL entity (the table name). The more +complex case takes a pair of a SQL entity and a SQL query. +In that second case, you can specify the columns by using +a pair of the table name and a sequence of column names. + +For the first case, you'll use the `:values` clause and you +may use the `:columns` clause as well. + +```clojure +user=> (sql/format {:insert-into :transport + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +user=> (sql/format {:insert-into :transport + :columns [:id :name] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +``` + +The second case: + +```clojure +user=> (sql/format '{insert-into (transport {select (id, name) from (cars)})}) +["INSERT INTO transport SELECT id, name FROM cars"] +user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})}) +["INSERT INTO transport (id, name) SELECT * FROM cars"] +``` + ## update + +`:update` expects either a simple SQL entity (table name) +or a pair of the table name and an alias: + +```clojure +user=> (sql/format {:update :transport + :set {:name "Yacht"} + :where [:= :id 2]}) +["UPDATE transport SET name = ? WHERE id = ?" "Yacht" 2] +``` + ## delete, delete-from + +`:delete-from` is the simple use case here, accepting just a +SQL entity (table name). `:delete` allows for deleting from +multiple tables, accepting a sequence of either table names +or aliases: + +```clojure +user=> (sql/format '{delete-from transport where (= id 1)}) +["DELETE FROM transport WHERE id = ?" 1] +user=> (sql/format {:delete [:order :item] + :from [:order] + :join [:item [:= :order.item-id :item.id]] + :where [:= :item.id 42]}) +["DELETE order, item FROM order INNER JOIN item ON order.item_id = item.id WHERE item.id = ?" 42] +``` + ## truncate + +`:truncate` accepts a simple SQL entity (table name): + +```clojure +user=> (sql/format '{truncate transport}) +["TRUNCATE transport"] +``` + ## columns + +Wherever you need just a list of column names `:columns` +accepts a sequence of SQL entities (names). We saw an +example above with `:insert-into`. + ## set (ANSI) + +`:set` accepts a hash map of SQL entities and the values +that they should be assigned. This precedence -- between +`:columns` and `:from` -- corresponds to ANSI SQL which +is correct for most databases. The MySQL dialect that +HoneySQL 2.0 supports has a different precedence (below). + +```clojure +user=> (sql/format {:update :order + :set {:line-count [:+ :line-count 1]} + :where [:= :item-id 42]}) +["UPDATE order SET line_count = line_count + ? WHERE item_id = ?" 1 42] +``` + ## from + +`:from` accepts a single sequence argument that lists +one or more SQL entities. Each entity can either be a +simple table name (keyword or symbol) or a pair of a +table name and an alias: + +```clojure +user=> (sql/format {:select [:username :name] + :from [:user :status] + :where [:and [:= :user.statusid :status.id] + [:= :user.id 9]]}) +["SELECT username, name FROM user, status WHERE (user.statusid = status.id) AND (user.id = ?)" 9] +user=> (sql/format {:select [:u.username :s.name] + :from [[:user :u] [:status :s]] + :where [:and [:= :u.statusid :s.id] + [:= :u.id 9]]}) +["SELECT u.username, s.name FROM user AS u, status AS s WHERE (u.statusid = s.id) AND (u.id = ?)" 9] +``` + ## using + ## join, left-join, right-join, inner-join, outer-join, full-join + ## cross-join + ## set (MySQL) + ## where + ## group-by + ## having + ## order-by + ## limit, offset (MySQL) + ## for + ## lock (MySQL) + ## values + ## on-conflict, on-constraint, do-nothing, do-update-set -## returning \ No newline at end of file + +## returning diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index e5ff1f9..d886ec5 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -44,8 +44,8 @@ (assoc {} k data))) (defn nest [& args] (generic :nest args)) -(defn with [& args] (generic :with args)) -(defn with-recursive [& args] (generic :with-recursive args)) +(defn with [& args] (generic-1 :with args)) +(defn with-recursive [& args] (generic-1 :with-recursive args)) ;; these five need to supply an empty hash map since they wrap ;; all of their arguments: (defn intersect [& args] (generic :intersect (cons {} args))) From 88ec86fd180ef53f2f98f5326ba23f132ba99157 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 04:47:08 -0800 Subject: [PATCH 116/254] Allow direction to default with expression --- src/honey/sql.cljc | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 7754021..46b9229 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -352,11 +352,12 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-order-by [k xs] - (let [dirs (map #(if (sequential? %) (second %) :asc) xs) + (let [dirs (map #(when (sequential? %) (second %)) xs) [sqls params] (format-expr-list (map #(if (sequential? %) (first %) %) xs))] (into [(str (sql-kw k) " " - (str/join ", " (map (fn [sql dir] (str sql " " (sql-kw dir))) + (str/join ", " (map (fn [sql dir] + (str sql " " (sql-kw (or dir :asc)))) sqls dirs)))] params))) From 16dd1fff4189768d7633cafa72bf09582733dc21 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 04:47:23 -0800 Subject: [PATCH 117/254] Update CTE test to verify both 1.x and 2.x --- test/honey/sql/helpers_test.cljc | 23 +++++++++++++++++++---- 1 file changed, 19 insertions(+), 4 deletions(-) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index b1e313c..90fe651 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -31,9 +31,13 @@ (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) (limit 50) (offset 10)) - m2 {:with [[:cte {:select [:*] - :from [:example] - :where [:= :example-column 0]}]] + ;; 2.0 allows :with to have a single pair instead + ;; of requiring a sequence of pairs and the `with` + ;; helper now creates just a pair so this test no + ;; longer wraps the CTE for comparison with m1: + m2 {:with [:cte {:select [:*] + :from [:example] + :where [:= :example-column 0]}] :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] :%now [[:raw "@x := 10"]]] :from [[:foo :f] [:baz :b]] @@ -52,11 +56,22 @@ :limit 50 :offset 10}] (testing "Various construction methods are consistent" + (is (= (clojure.core/set (keys m1)) (clojure.core/set (keys m2)))) + (doseq [k (keys m1)] + (is (= (get m1 k) (get m2 k)))) (is (= m1 m2))) (testing "SQL data formats correctly" (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) + (sql/format m1 {:params {:param1 "gabba" :param2 2}}))) + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format m2 {:params {:param1 "gabba" :param2 2}}))) + ;; also test that m2 formats the same way with nested CTE like 2.x: + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format (clojure.core/update m2 :with vector) + {:params {:param1 "gabba" :param2 2}})))) #?(:clj (testing "SQL data prints and reads correctly" (is (= m1 (read-string (pr-str m1)))))) #_(testing "SQL data formats correctly with alternate param naming" From c39f1b49ee1cdb8f8a28c3c130edb2bff671ea2d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 04:47:31 -0800 Subject: [PATCH 118/254] More clause docs --- doc/clause-reference.md | 47 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 47 insertions(+) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 3452ccf..0263974 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -212,14 +212,61 @@ user=> (sql/format {:select [:u.username :s.name] ## set (MySQL) +This is the precedence of the `:set` clause for the MySQL dialect. +It is otherwise identical to the `:set` clause described above. + ## where +The `:where` clause can have a single SQL expression, or +a sequence of SQL expressions prefixed by either `:and` +or `:or`. See examples of `:where` in various clauses above. + ## group-by +`:group-by` accepts a sequence of one or more SQL expressions. + +```clojure +user=> (sql/format '{select (*) from (table) + group-by (status, (year created-date))}) +["SELECT * FROM table GROUP BY status, YEAR(created_date)"] +``` + ## having +The `:having` clause works identically to `:where` above +but is rendered into the SQL later in precedence order. + ## order-by +`:order-by` accepts a sequence of one or more ordering +expressions. Each ordering expression is either a simple +SQL entity or a pair of a SQL expression and a direction +(which can be `:asc` or `:desc` -- or the symbol equivalent). + +If you want to order by an expression, you should wrap it +as a pair with a direction: + +```clojure +user=> (sql/format '{select (*) from table + ;; simple orderings: + order-by (status, created-date)}) +["SELECT * FROM table ORDER BY status ASC, created_date ASC"] +user=> (sql/format '{select (*) from table + ;; explicit direction provided: + order-by ((status asc), ((year created-date) asc))}) +["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"] +``` + +The default direction is ascending and if you provide a wrapped +expression you _can_ omit the direction if you want: + +```clojure +user=> (sql/format {:select [:*] :from :table + ;; expression without direction is still wrapped: + :order-by [:status, [[:year :created-date]]]}) +["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"] +``` + ## limit, offset (MySQL) ## for From d2a08c17ef74295a3964836b2002bc5f2a8f6e03 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 05:13:39 -0800 Subject: [PATCH 119/254] More docs --- doc/clause-reference.md | 24 ++++++++++++++++++++++++ 1 file changed, 24 insertions(+) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 0263974..8c63f94 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -208,6 +208,30 @@ user=> (sql/format {:select [:u.username :s.name] ## join, left-join, right-join, inner-join, outer-join, full-join +All these join clauses have the same structure: they accept a sequence +of alternating SQL entities (table names) and conditions that specify +how to perform the join. The table names can either be simple names +or a pair of a table name and an alias: + +```clojure +user=> (sql/format {:select [:u.username :s.name] + :from [[:user :u]] + :join [[:status :s] [:= :u.statusid :s.id]] + :where [:= :s.id 2]}) +["SELECT u.username, s.name FROM user AS u INNER JOIN status AS s ON u.statusid = s.id WHERE s.id = ?" 2] +``` + +An alternative to a join condition is a `USING` expression: + +```clojure +user=> (sql/format {:select [:t.ref :pp.code] + :from [[:transaction :t]] + :left-join [[:paypal-tx :pp] + [:using :id]] + :where [:= "settled" :pp.status]}) +["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) WHERE ? = pp.status" "settled"] +``` + ## cross-join ## set (MySQL) From 09745c723701e094c824471c9add23fb38af6a6f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 16:36:52 -0800 Subject: [PATCH 120/254] Document :using --- doc/clause-reference.md | 13 +++++++++++++ 1 file changed, 13 insertions(+) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 8c63f94..a853dd0 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -204,8 +204,21 @@ user=> (sql/format {:select [:u.username :s.name] ["SELECT u.username, s.name FROM user AS u, status AS s WHERE (u.statusid = s.id) AND (u.id = ?)" 9] ``` +> Note: the actual formatting of a `:from` clause is currently identical to the formatting of a `:select` clause. + ## using +`:using` accepts a single sequence argument that lists +one or more SQL entities. Each entity can either be a +simple table name (keyword or symbol) or a pair of a +table name and an alias. + +`:using` is intended to be used as a simple join with a `:delete-from` +clause (see [PostgreSQL DELETE statement](https://www.postgresql.org/docs/12/sql-delete.html) +for more detail). + +> Note: the actual formatting of a `:using` clause is currently identical to the formatting of a `:select` clause. + ## join, left-join, right-join, inner-join, outer-join, full-join All these join clauses have the same structure: they accept a sequence From c8fe84cbb4b617681feaf7075daaca95631bf1dc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Feb 2021 08:41:11 -0800 Subject: [PATCH 121/254] Document values --- doc/clause-reference.md | 37 +++++++++++++++++++++++++++++++++++++ 1 file changed, 37 insertions(+) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index a853dd0..b562918 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -95,6 +95,9 @@ user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]] `:select-distinct` works the same way but produces `SELECT DISTINCT`. +HoneySQL does not yet support `SELECT .. INTO ..` +or `SELECT .. BULK COLLECT INTO ..`. + ## insert-into There are two use cases with `:insert-into`. The first case @@ -247,6 +250,13 @@ user=> (sql/format {:select [:t.ref :pp.code] ## cross-join +`:cross-join` accepts a single sequence argument that lists +one or more SQL entities. Each entity can either be a +simple table name (keyword or symbol) or a pair of a +table name and an alias. + +> Note: the actual formatting of a `:cross-join` clause is currently identical to the formatting of a `:select` clause. + ## set (MySQL) This is the precedence of the `:set` clause for the MySQL dialect. @@ -312,6 +322,33 @@ user=> (sql/format {:select [:*] :from :table ## values +`:values` accepts either a sequence of hash maps representing +row values or a sequence of sequences, also representing row +values. + +In the former case, all of the rows are augmented to have +`nil` values for any missing keys (columns). In the latter, +all of the rows are padded to the same length by adding `nil` +values if needed. + +```clojure +user=> (sql/format {:insert-into :table + :values [[1 2] [2 3 4 5] [3 4 5]]}) +["INSERT INTO table VALUES (?, ?, NULL, NULL), (?, ?, ?, ?), (?, ?, ?, NULL)" 1 2 2 3 4 5 3 4 5] +user=> (sql/format '{insert-into table + values ({id 1 name "Sean"} + {id 2} + {name "Extra"})}) +["INSERT INTO table (id, name) VALUES (?, ?), (?, NULL), (NULL, ?)" 1 "Sean" 2 "Extra"] +``` + ## on-conflict, on-constraint, do-nothing, do-update-set ## returning + +`:returning` accepts a single sequence argument that lists +one or more SQL entities. Each entity can either be a +simple table name (keyword or symbol) or a pair of a +table name and an alias. + +> Note: the actual formatting of a `:returning` clause is currently identical to the formatting of a `:select` clause. From 9f579f492a26e8078da8074a82b9aea4aabaeb0c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 8 Feb 2021 12:48:33 -0800 Subject: [PATCH 122/254] Allow symbols in for/lock clauses --- src/honey/sql.cljc | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 46b9229..0e9fdae 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -366,7 +366,11 @@ [(str (sql-kw k) " " (sql-kw strength) (when tables (str - (cond (#{:nowait :skip-locked :wait} tables) + (cond (and (keyword? tables) + (#{:nowait :skip-locked :wait} tables)) + (str " " (sql-kw tables)) + (and (symbol? tables) + ('#{nowait skip-locked wait} tables)) (str " " (sql-kw tables)) (sequential? tables) (str " OF " From 2c9be16d973ec27bac4eb7562df11b3e85d4055a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 8 Feb 2021 12:48:42 -0800 Subject: [PATCH 123/254] Finish the clause docs --- doc/clause-reference.md | 89 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 89 insertions(+) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index b562918..2a4c4a0 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -316,10 +316,63 @@ user=> (sql/format {:select [:*] :from :table ## limit, offset (MySQL) +Both `:limit` and `:offset` expect a single SQL expression: + +```clojure +user=> (sql/format {:select [:id :name] + :from [:table] + :limit 20 :offset 20}) +["SELECT id, name FROM table LIMIT ? OFFSET ?" 20 20] +``` + +> Note: In the prerelease, these MySQL-specific clauses are in the default dialect but these will be moved to the `:mysql` dialect. + ## for +The `:for` clause accepts either a single item -- the lock +strength -- or a sequence of up to three items of which the +first is the lock strength, followed by an optional table +name (or sequence of table names), followed by how to deal +with the lock: + +```clojure +user=> (sql/format '{select (*) from (table) + for update}) +["SELECT * FROM table FOR UPDATE"] +user=> (sql/format '{select (*) from (table) + for no-key-update}) +["SELECT * FROM table FOR NO KEY UPDATE"] +user=> (sql/format '{select (*) from (table) + for (key-share wait)}) +["SELECT * FROM table FOR KEY SHARE WAIT"] +user=> (sql/format '{select (*) from (table) + for (update bar wait)}) +["SELECT * FROM table FOR UPDATE OF bar WAIT"] +user=> (sql/format '{select (*) from (table) + for (update (bar quux) wait)}) +["SELECT * FROM table FOR UPDATE OF bar, quux WAIT"] +``` + +The lock strength can be any SQL keyword or phrase +represented as a Clojure keyword (or symbol), with +spaces represented by `-`. + +The three SQL keywords/phrases that are recognized +as not being a table name in the second slot are +`NOWAIT`, `SKIP LOCKED`, and `WAIT`. + +However, in the case where a table name (or sequence +of table names) is present, no check is made on the +keyword or phrase in that third slot (although it is +expected to be just one of those three mentioned above). + ## lock (MySQL) +The syntax accepted for MySQL's `:lock` is exactly the +same as the `:for` clause above. + +> Note: In the prerelease, this MySQL-specific clauses is in the default dialect but this will be moved to the `:mysql` dialect. + ## values `:values` accepts either a sequence of hash maps representing @@ -344,6 +397,42 @@ user=> (sql/format '{insert-into table ## on-conflict, on-constraint, do-nothing, do-update-set +These are grouped together because they are handled +as if they are separate clauses but they will appear +in pairs: `ON ... DO ...`. + +`:on-conflict` accepts either a single SQL entity +(a keyword or symbol) or a SQL clause. That's either +a column name or an `:on-constraint` clause or a +`:where` clause. + +`:on-constraint` accepts a single SQL entity that +identifies a constraint name. + +Since `:do-nothing` is a SQL clause but has no +associated data, it still has to have an arbitrary +value because clauses are hash maps and that value +will be ignored so `:do-nothing true` is a +reasonable choices. + +`:do-update-set` accepts either a single SQL entity +(a keyword or symbol) or hash map of columns and +values, like `:set` (above). The former produces +a `SET` clause using `EXCLUDED`: + +```clojure +user=> (sql/format {:insert-into :companies + :values [{:name "Microsoft"}] + :on-conflict :name + :do-update-set :name}) +["INSERT INTO companies (name) VALUES (?) ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name" "Microsoft"] +user=> (sql/format {:insert-into :companies + :values [{:name "Microsoft"}] + :on-conflict {:on-constraint :name-idx} + :do-nothing true}) +["INSERT INTO companies (name) VALUES (?) ON CONFLICT ON CONSTRAINT name_idx DO NOTHING" "Microsoft"] +``` + ## returning `:returning` accepts a single sequence argument that lists From 8f725abe02c83f2ea3d7c175e7d38dc99d24b9eb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 11:49:32 -0800 Subject: [PATCH 124/254] Revert "Update CTE test to verify both 1.x and 2.x" This reverts commit 16dd1fff4189768d7633cafa72bf09582733dc21. --- test/honey/sql/helpers_test.cljc | 23 ++++------------------- 1 file changed, 4 insertions(+), 19 deletions(-) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 90fe651..b1e313c 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -31,13 +31,9 @@ (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) (limit 50) (offset 10)) - ;; 2.0 allows :with to have a single pair instead - ;; of requiring a sequence of pairs and the `with` - ;; helper now creates just a pair so this test no - ;; longer wraps the CTE for comparison with m1: - m2 {:with [:cte {:select [:*] - :from [:example] - :where [:= :example-column 0]}] + m2 {:with [[:cte {:select [:*] + :from [:example] + :where [:= :example-column 0]}]] :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] :%now [[:raw "@x := 10"]]] :from [[:foo :f] [:baz :b]] @@ -56,22 +52,11 @@ :limit 50 :offset 10}] (testing "Various construction methods are consistent" - (is (= (clojure.core/set (keys m1)) (clojure.core/set (keys m2)))) - (doseq [k (keys m1)] - (is (= (get m1 k) (get m2 k)))) (is (= m1 m2))) (testing "SQL data formats correctly" (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format m1 {:params {:param1 "gabba" :param2 2}}))) - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format m2 {:params {:param1 "gabba" :param2 2}}))) - ;; also test that m2 formats the same way with nested CTE like 2.x: - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format (clojure.core/update m2 :with vector) - {:params {:param1 "gabba" :param2 2}})))) + (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) #?(:clj (testing "SQL data prints and reads correctly" (is (= m1 (read-string (pr-str m1)))))) #_(testing "SQL data formats correctly with alternate param naming" From e02b5b5c8269eff438c0d7fd877a0699c60464d0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 11:50:00 -0800 Subject: [PATCH 125/254] Revert "Document with / CTE" This reverts commit c00fbffe30398ea70be6c36e277e3df9ad265902. --- doc/clause-reference.md | 47 ---------------------------------------- doc/getting-started.md | 2 +- src/honey/sql.cljc | 33 +++++++++++++--------------- test/honey/sql_test.cljc | 14 ------------ 4 files changed, 16 insertions(+), 80 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 2a4c4a0..613972d 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -12,54 +12,7 @@ Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. ## nest - -This is pseudo-syntax that lets you wrap a substatement -in an extra level of parentheses. It should rarely be -needed and it is mostly present to provide the same -functionality for clauses that `[:nest ..]` provides -for expressions. - ## with, with-recursive - -These provide CTE support for SQL Server. The argument to -`:with` (or `:with-recursive`) is a pair of -a result set name (or description) and a basic SQL statement. -The result set can either be a SQL entity (a simple name) -or a pair of a SQL entity and a set of column names. - -```clojure -user=> (sql/format '{with (stuff {select (:*) from (foo)}) - select (id,name) - from (stuff) - where (= status 0)}) -["WITH stuff AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0] -``` - -You can specify a list of columns for the CTE like this: - -```clojure -user=> (sql/format {:with [[:stuff {:columns [:id :name]}] - {:select [:*] :from [:foo]}] - :select [:id :name] - :from [:stuff] - :where [:= :status 0]}) -["WITH stuff (id, name) AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0] -``` - -You can use a `VALUES` clause in the CTE: - -```clojure -user=> (sql/format {:with [[:stuff {:columns [:id :name]}] - {:values [[1 "Sean"] [2 "Jay"]]}] - :select [:id :name] - :from [:stuff]}) -["WITH stuff (id, name) AS (VALUES (?, ?), (?, ?)) SELECT id, name FROM stuff" 1 "Sean" 2 "Jay"] -``` - -`:with-recursive` follows the same rules as `:with` and produces `WITH RECURSIVE` instead of just `WITH`. - -> Note: HoneySQL 0.6.2 introduced support for CTEs a long time ago and it expected the pair (of result set and query) to be wrapped in a sequence, even though you can only have a single CTE. For backward compatibility, HoneySQL 2.0 accepts that format but it should be considered deprecated. - ## intersect, union, union-all, except, except-all These all expect a sequence of SQL clauses, those clauses diff --git a/doc/getting-started.md b/doc/getting-started.md index e8b986e..8941caa 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -47,7 +47,7 @@ values identified in the SQL expressions: ;;=> ["SELECT * FROM table WHERE id = ?" 1] ``` -By default, any values found in the data structure, that are not keywords +Any values found in the data structure, that are not keywords or symbols, are treated as positional parameters and replaced by `?` in the SQL string and lifted out into the vector that is returned from `format`. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0e9fdae..a137515 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -278,24 +278,21 @@ [(format-entity x)])) (defn- format-with [k xs] - ;; 1.x and earlier required a sequence of pairs -- X AS expr -- where - ;; X is either [entity expr] or just entity; but a CTE can only contain - ;; one result set definition so 2.x allows this to be just a pair instead - (let [[result-set query] - (case (count xs) - 1 (if (= 2 (count (first xs))) - (first xs) - (throw (ex-info (str k " expects a sequence with just a single pair") - {:elements (count xs)}))) - 2 xs - (throw (ex-info (str k " expects a pair (result set, query)") - {:elements (count xs)}))) - [sql & params] (format-with-part result-set) - [sql' & params'] (format-dsl query)] - ;; according to docs, CTE should _always_ be wrapped: - (cond-> [(str (sql-kw k) " " sql " AS " (str "(" sql' ")"))] - params (into params) - params' (into params')))) + ;; TODO: a sequence of pairs -- X AS expr -- where X is either [entity expr] + ;; or just entity, as far as I can tell... + (let [[sqls params] + (reduce (fn [[sql params] [sql' & params']] + [(conj sql sql') (if params' (into params params') params)]) + [[] []] + (map (fn [[x expr]] + (let [[sql & params] (format-with-part x) + [sql' & params'] (format-dsl expr)] + ;; according to docs, CTE should _always_ be wrapped: + (cond-> [(str sql " AS " (str "(" sql' ")"))] + params (into params) + params' (into params')))) + xs))] + (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-selector [k xs] (format-selects k [xs])) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index ccb0cb2..714f775 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -97,7 +97,6 @@ (format {:select [:vals.a] :from [[{:values [[1 2 3]]} [:vals {:columns [:a :b :c]}]]]})))) (deftest test-cte - ;; 1.x and earlier with the extra sequence wrapping: (is (= (format {:with [[:query {:select [:foo] :from [:bar]}]]}) ["WITH query AS (SELECT foo FROM bar)"])) (is (= (format {:with-recursive [[:query {:select [:foo] :from [:bar]}]]}) @@ -109,19 +108,6 @@ {:values [[1 2] [4 5 6]]}]] :select [:*] :from [:static]}) - ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6])) - ;; 2.x should allow just a pair: - (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]]}]}) - ["WITH static (a, b, c) AS (VALUES (?, ?, ?), (?, ?, NULL))" 1 2 3 4 5])) - (is (= (format - {:with [[:static {:columns [:a :b :c]}] - {:values [[1 2] [4 5 6]]}] - :select [:*] - :from [:static]}) ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6]))) (deftest insert-into From 0a83601c3c145258ac4edc58cde0436ffaddbaa9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 12:04:53 -0800 Subject: [PATCH 126/254] Fixes #298 by restoring multi-CTE capability Reverts code changes that stripped the sequence support. Updates the docs to clarify how sequence support works. --- doc/clause-reference.md | 46 ++++++++++++++++++++++++++++++++++++++ doc/getting-started.md | 2 +- src/honey/sql/helpers.cljc | 4 ++-- test/honey/sql_test.cljc | 5 +++++ 4 files changed, 54 insertions(+), 3 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 613972d..5933e67 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -12,7 +12,53 @@ Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. ## nest + +This is pseudo-syntax that lets you wrap a substatement +in an extra level of parentheses. It should rarely be +needed and it is mostly present to provide the same +functionality for clauses that `[:nest ..]` provides +for expressions. + ## with, with-recursive + +These provide CTE support for SQL Server. The argument to +`:with` (or `:with-recursive`) is a sequences of pairs, each of +a result set name (or description) and a basic SQL statement. +The result set can either be a SQL entity (a simple name) +or a pair of a SQL entity and a set of column names. + +```clojure +user=> (sql/format '{with ((stuff {select (:*) from (foo)}), + (nonsense {select (:*) from (bar)})) + select (foo.id,bar.name) + from (stuff, nonsense) + where (= status 0)}) +["WITH stuff AS (SELECT * FROM foo), nonsense AS (SELECT * FROM bar) SELECT foo.id, bar.name FROM stuff, nonsense WHERE status = ?" 0] +``` + +You can specify a list of columns for the CTE like this: + +```clojure +user=> (sql/format {:with [[[:stuff {:columns [:id :name]}] + {:select [:*] :from [:foo]}]] + :select [:id :name] + :from [:stuff] + :where [:= :status 0]}) +["WITH stuff (id, name) AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0] +``` + +You can use a `VALUES` clause in the CTE: + +```clojure +user=> (sql/format {:with [[[:stuff {:columns [:id :name]}] + {:values [[1 "Sean"] [2 "Jay"]]}]] + :select [:id :name] + :from [:stuff]}) +["WITH stuff (id, name) AS (VALUES (?, ?), (?, ?)) SELECT id, name FROM stuff" 1 "Sean" 2 "Jay"] +``` + +`:with-recursive` follows the same rules as `:with` and produces `WITH RECURSIVE` instead of just `WITH`. + ## intersect, union, union-all, except, except-all These all expect a sequence of SQL clauses, those clauses diff --git a/doc/getting-started.md b/doc/getting-started.md index 8941caa..e8b986e 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -47,7 +47,7 @@ values identified in the SQL expressions: ;;=> ["SELECT * FROM table WHERE id = ?" 1] ``` -Any values found in the data structure, that are not keywords +By default, any values found in the data structure, that are not keywords or symbols, are treated as positional parameters and replaced by `?` in the SQL string and lifted out into the vector that is returned from `format`. diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index d886ec5..e5ff1f9 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -44,8 +44,8 @@ (assoc {} k data))) (defn nest [& args] (generic :nest args)) -(defn with [& args] (generic-1 :with args)) -(defn with-recursive [& args] (generic-1 :with-recursive args)) +(defn with [& args] (generic :with args)) +(defn with-recursive [& args] (generic :with-recursive args)) ;; these five need to supply an empty hash map since they wrap ;; all of their arguments: (defn intersect [& args] (generic :intersect (cons {} args))) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 714f775..3ba5a5f 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -99,6 +99,11 @@ (deftest test-cte (is (= (format {:with [[:query {:select [:foo] :from [:bar]}]]}) ["WITH query AS (SELECT foo FROM bar)"])) + (is (= (format {:with [[:query1 {:select [:foo] :from [:bar]}] + [:query2 {:select [:bar] :from [:quux]}]] + :select [:query1.id :query2.name] + :from [:query1 :query2]}) + ["WITH query1 AS (SELECT foo FROM bar), query2 AS (SELECT bar FROM quux) SELECT query1.id, query2.name FROM query1, query2"])) (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]]}]]}) From 5318c184e6d25e71edf25268a9797c9333c0d99b Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 15:07:16 -0800 Subject: [PATCH 127/254] Addresses #293 by expanding insert-into behavior This adds alias support into `:insert-into`. It also adds some tests for the PostgreSQL-specific stuff currently in nilenso's library. --- doc/clause-reference.md | 54 ++++++++++---- src/honey/sql.cljc | 28 +++++--- src/honey/sql/helpers.cljc | 4 +- test/honey/sql/helpers_test.cljc | 120 ++++++++++++++++++++++++++++++- 4 files changed, 179 insertions(+), 27 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 5933e67..0be782c 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -99,16 +99,24 @@ or `SELECT .. BULK COLLECT INTO ..`. ## insert-into -There are two use cases with `:insert-into`. The first case -takes just a simple SQL entity (the table name). The more -complex case takes a pair of a SQL entity and a SQL query. -In that second case, you can specify the columns by using -a pair of the table name and a sequence of column names. +There are three use cases with `:insert-into`. -For the first case, you'll use the `:values` clause and you -may use the `:columns` clause as well. +The first case takes just a table specifier (either a +table name or a table/alias pair), +and then you can optionally specify the columns (via a `:columns` clause). + +The second case takes a pair of a table specifier (either a +table name or table/alias pair) and a sequence of column +names (so you do not need to also use `:columns`). + +The third case takes a pair of either a table specifier +or a table/column specifier and a SQL query. + +For the first and second cases, you'll use the `:values` clause +to specify rows of values to insert. ```clojure +;; first case -- table specifier: user=> (sql/format {:insert-into :transport :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) ["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] @@ -116,15 +124,37 @@ user=> (sql/format {:insert-into :transport :columns [:id :name] :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) ["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] -``` - -The second case: - -```clojure +;; with an alias: +user=> (sql/format {:insert-into [:transport :t] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +user=> (sql/format {:insert-into [:transport :t] + :columns [:id :name] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +;; second case -- table specifier and columns: +user=> (sql/format {:insert-into [:transport [:id :name]] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +;; with an alias: +user=> (sql/format {:insert-into [[:transport :t] [:id :name]] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) +["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"] +;; third case -- table/column specifier and query: user=> (sql/format '{insert-into (transport {select (id, name) from (cars)})}) ["INSERT INTO transport SELECT id, name FROM cars"] +;; with columns: user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})}) ["INSERT INTO transport (id, name) SELECT * FROM cars"] +;; with an alias: +user=> (sql/format '{insert-into ((transport t) {select (id, name) from (cars)})}) +["INSERT INTO transport AS t SELECT id, name FROM cars"] +;; with columns: +user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})}) +["INSERT INTO transport (id, name) SELECT * FROM cars"] +;; with an alias and columns: +user=> (sql/format '{insert-into (((transport t) (id, name)) {select (*) from (cars)})}) +["INSERT INTO transport AS t (id, name) SELECT * FROM cars"] ``` ## update diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a137515..ee58369 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -299,21 +299,27 @@ (defn- format-insert [k table] (if (sequential? table) - (cond (sequential? (first table)) - (let [[[table cols] statement] table + (cond (map? (second table)) + (let [[table statement] table + [table cols] + (if (and (sequential? table) (sequential? (second table))) + table + [table]) [sql & params] (format-dsl statement)] (into [(str (sql-kw k) " " (format-entity-alias table) - " (" - (str/join ", " (map #'format-entity-alias cols)) - ") " + " " + (when (seq cols) + (str "(" + (str/join ", " (map #'format-entity-alias cols)) + ") ")) sql)] params)) - (map? (second table)) - (let [[table statement] table - [sql & params] (format-dsl statement)] - (into [(str (sql-kw k) " " (format-entity-alias table) - " " sql)] - params)) + (sequential? (second table)) + (let [[table cols] table] + [(str (sql-kw k) " " (format-entity-alias table) + " (" + (str/join ", " (map #'format-entity-alias cols)) + ")")]) :else [(str (sql-kw k) " " (format-entity-alias table))]) [(str (sql-kw k) " " (format-entity-alias table))])) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index e5ff1f9..616fd26 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -80,10 +80,10 @@ (defn offset [& args] (generic-1 :offset args)) (defn for [& args] (generic-1 :for args)) (defn values [& args] (generic-1 :values args)) -(defn on-conflict [& args] (generic :on-conflict args)) +(defn on-conflict [& args] (generic-1 :on-conflict args)) (defn on-constraint [& args] (generic :on-constraint args)) (defn do-nothing [& args] (generic :do-nothing args)) -(defn do-update-set [& args] (generic :do-update-set args)) +(defn do-update-set [& args] (generic-1 :do-update-set args)) (defn returning [& args] (generic :returning args)) ;; helpers that produce non-clause expressions -- must be listed below: diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index b1e313c..df88f04 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -6,8 +6,10 @@ :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] [honey.sql.helpers - :refer [columns cross-join from full-join group-by having insert-into - join left-join limit offset order-by right-join + :refer [columns cross-join do-update-set from full-join + group-by having insert-into + join left-join limit offset on-conflict order-by + returning right-join select select-distinct values where with]])) (deftest test-select @@ -274,3 +276,117 @@ " AND (location NOT LIKE '/0/%')" " AND (location NOT LIKE '/1/%')")] (stack-overflow-282 2)))) + +(deftest issue-293 + ;; these tests are based on the README at https://github.com/nilenso/honeysql-postgres + (is (= (-> (insert-into :distributors) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (-> (on-conflict :did) + (do-update-set :dname)) + (returning :*) + sql/format) + [(str "INSERT INTO distributors (did, dname)" + " VALUES (?, ?), (?, ?)" + " ON CONFLICT (did)" + " DO UPDATE SET dname = EXCLUDED.dname" + " RETURNING *") + 5 "Gizmo Transglobal" + 6 "Associated Computing, Inc"])) + (is (= (-> (insert-into :distributors) + (values [{:did 23 :dname "Foo Distributors"}]) + (on-conflict :did) + ;; instead of do-update-set! + (do-update-set {:dname [:|| :EXCLUDED.dname " (formerly " :distributors.dname ")"] + :downer :EXCLUDED.downer}) + sql/format) + [(str "INSERT INTO distributors (did, dname)" + " VALUES (?, ?)" + " ON CONFLICT (did)" + " DO UPDATE SET dname = EXCLUDED.dname || ? || distributors.dname || ?," + " downer = EXCLUDED.downer") + 23 "Foo Distributors" " (formerly " ")"]))) + +(deftest issue-293-insert-into-data + ;; insert into as (and other tests) based on :insert-into + ;; examples in the clause reference docs: + ;; first case -- table specifier: + (is (= (sql/format {:insert-into :transport + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + (is (= (sql/format {:insert-into :transport + :columns [:id :name] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; with an alias: + (is (= (sql/format {:insert-into [:transport :t] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + (is (= (sql/format {:insert-into [:transport :t] + :columns [:id :name] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; second case -- table specifier and columns: + (is (= (sql/format {:insert-into [:transport [:id :name]] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; with an alias: + (is (= (sql/format {:insert-into [[:transport :t] [:id :name]] + :values [[1 "Car"] [2 "Boat"] [3 "Bike"]]}) + ["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; third case -- table/column specifier and query: + (is (= (sql/format '{insert-into (transport {select (id, name) from (cars)})}) + ["INSERT INTO transport SELECT id, name FROM cars"])) + ;; with columns: + (is (= (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})}) + ["INSERT INTO transport (id, name) SELECT * FROM cars"])) + ;; with an alias: + (is (= (sql/format '{insert-into ((transport t) {select (id, name) from (cars)})}) + ["INSERT INTO transport AS t SELECT id, name FROM cars"])) + ;; with columns: + (is (= (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})}) + ["INSERT INTO transport (id, name) SELECT * FROM cars"])) + ;; with an alias and columns: + (is (= (sql/format '{insert-into (((transport t) (id, name)) {select (*) from (cars)})}) + ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"]))) + +(deftest issue-293-insert-into-helpers + ;; and the same set of tests using the helper functions instead: + (is (= (sql/format (-> (insert-into :transport) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + (is (= (sql/format (-> (insert-into :transport) + (columns :id :name) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; with an alias: + (is (= (sql/format (-> (insert-into :transport :t) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport AS t VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + (is (= (sql/format (-> (insert-into :transport :t) + (columns :id :name) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; second case -- table specifier and columns: + (is (= (sql/format (-> (insert-into :transport [:id :name]) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; with an alias: + (is (= (sql/format (-> (insert-into [:transport :t] [:id :name]) + (values [[1 "Car"] [2 "Boat"] [3 "Bike"]]))) + ["INSERT INTO transport AS t (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"])) + ;; third case -- table/column specifier and query: + (is (= (sql/format (insert-into :transport '{select (id, name) from (cars)})) + ["INSERT INTO transport SELECT id, name FROM cars"])) + ;; with columns: + (is (= (sql/format (insert-into [:transport [:id :name]] '{select (*) from (cars)})) + ["INSERT INTO transport (id, name) SELECT * FROM cars"])) + ;; with an alias: + (is (= (sql/format (insert-into '(transport t) '{select (id, name) from (cars)})) + ["INSERT INTO transport AS t SELECT id, name FROM cars"])) + ;; with columns: + (is (= (sql/format (insert-into '(transport (id, name)) '{select (*) from (cars)})) + ["INSERT INTO transport (id, name) SELECT * FROM cars"])) + ;; with an alias and columns: + (is (= (sql/format (insert-into ['(transport t) '(id, name)] '{select (*) from (cars)})) + ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"]))) From e157aec976769e4cfad0e63f0bad665ba5068e01 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 16:25:31 -0800 Subject: [PATCH 128/254] Addresses #293 by adding over, partition-by, and window --- doc/clause-reference.md | 53 ++++++++++++++++++++++++++++++++ doc/special-syntax.md | 14 +++++++++ src/honey/sql.cljc | 22 +++++++++++-- src/honey/sql/helpers.cljc | 8 +++-- test/honey/sql/helpers_test.cljc | 30 ++++++++++++++++-- 5 files changed, 120 insertions(+), 7 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 0be782c..d0e63fa 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -312,6 +312,59 @@ user=> (sql/format '{select (*) from (table) The `:having` clause works identically to `:where` above but is rendered into the SQL later in precedence order. +## window, partition-by (and over) + +`:window` accepts a pair of SQL entity (the window name) +and the window "function" as a SQL clause (a hash map). + +`:partition-by` accepts the same arguments as `:select` above +(even though the allowable SQL generated is much more restrictive). + +These are expected to be used with the `:over` expression (special syntax). + +```clojure +user=> (sql/format {:select [:id + [[:over + [[:avg :salary] + {:partition-by [:department] + :order-by [:designation]} + :Average] + [[:max :salary] + :w + :MaxSalary]]]] + :from [:employee] + :window [:w {:partition-by [:department]}]}) +["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] +;; easier to write with helpers (and easier to read!): +user=> (sql/format (-> (select :id + (over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average] + [[:max :salary] :w :MaxSalary])) + (from :employee) + (window :w (partition-by :department)))) +["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] +``` + +The window function in the `:over` expression may be `{}` or `nil`: + +```clojure +user=> (sql/format {:select [:id + [[:over + [[:avg :salary] + {} + :Average] + [[:max :salary] + nil + :MaxSalary]]]] + :from [:employee]}) +["SELECT id, AVG(salary) OVER () AS Average, MAX(salary) OVER () AS MaxSalary FROM employee"] +;; easier to write with helpers (and easier to read!): +user=> (sql/format (-> (select :id + (over [[:avg :salary] {} :Average] + [[:max :salary] nil :MaxSalary])) + (from :employee))) +["SELECT id, AVG(salary) OVER () AS Average, MAX(salary) OVER () AS MaxSalary FROM employee"] +``` + ## order-by `:order-by` accepts a sequence of one or more ordering diff --git a/doc/special-syntax.md b/doc/special-syntax.md index d3be25a..df6f088 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -128,6 +128,20 @@ in front of it: ;;=> ["NOT x = ?" 42] ``` +## over + +This is intended to be used with the `:window` and `:partition-by` clauses. + +`:over` takes any number of window expressions which are either pairs or triples +that have an aggregation expression, a window function, and an optional alias. + +The window function may either be a SQL entity (named in a `:window` clause) +or a SQL clause that describes the window (e.g., using `:partition-by` and/or `:order-by`). + +Since a function call (using `:over`) needs to be wrapped in a sequence for a +`:select` clause, it is usually easier to use the `over` helper function +to construct this expression. + ## param Used to identify a named parameter in a SQL expression diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index ee58369..3d4e935 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -41,7 +41,9 @@ :columns :set :from :using :join :left-join :right-join :inner-join :outer-join :full-join :cross-join - :where :group-by :having :order-by :limit :offset :for :values + :where :group-by :having + :window :partition-by + :order-by :limit :offset :for :values :on-conflict :on-constraint :do-nothing :do-update-set :returning]) @@ -266,7 +268,7 @@ (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-selectable-dsl % {:as (#{:select :from} k)}) xs))] + (map #(format-selectable-dsl % {:as (#{:select :from :window} k)}) xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) (let [[sql & params] (format-selectable-dsl xs {:as (#{:select :from} k)})] (into [(str (sql-kw k) " " sql)] params)))) @@ -500,6 +502,8 @@ :where #'format-on-expr :group-by #'format-group-by :having #'format-on-expr + :window #'format-selector + :partition-by #'format-selects :order-by #'format-order-by :limit #'format-on-expr :offset #'format-on-expr @@ -664,6 +668,20 @@ (fn [_ [x]] (let [[sql & params] (format-expr x)] (into [(str "NOT " sql)] params))) + :over + (fn [_ [& args]] + (let [[sqls params] + (reduce (fn [[sqls params] [e p a]] + (let [[sql-e & params-e] (format-expr e) + [sql-p & params-p] (if (or (nil? p) (map? p)) + (format-dsl p {:nested true}) + [(format-entity p)])] + [(conj sqls (str sql-e " OVER " sql-p + (when a (str " AS " (format-entity a))))) + (-> params (into params-e) (into params-p))])) + [[] []] + args)] + (into [(str/join ", " sqls)] params))) :param (fn [_ [k]] ["?" (->param k)]) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 616fd26..4b67300 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -2,7 +2,7 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." - (:refer-clojure :exclude [update set group-by for]) + (:refer-clojure :exclude [update set group-by for partition-by]) (:require [honey.sql :as h])) (defn- default-merge [current args] @@ -75,6 +75,8 @@ (defn where [& args] (generic :where args)) (defn group-by [& args] (generic :group-by args)) (defn having [& args] (generic :having args)) +(defn window [& args] (generic :window args)) +(defn partition-by [& args] (generic :partition-by args)) (defn order-by [& args] (generic :order-by args)) (defn limit [& args] (generic-1 :limit args)) (defn offset [& args] (generic-1 :offset args)) @@ -88,8 +90,10 @@ ;; helpers that produce non-clause expressions -- must be listed below: (defn composite [& args] (into [:composite] args)) +;; to make this easy to use in a select, wrap it so it becomes a function: +(defn over [& args] [(into [:over] args)]) #?(:clj (assert (= (clojure.core/set (conj @@#'h/base-clause-order - :composite)) + :composite :over)) (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index df88f04..f3e62c9 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -1,7 +1,7 @@ ;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql.helpers-test - (:refer-clojure :exclude [update set group-by for]) + (:refer-clojure :exclude [update set group-by for partition-by]) (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] @@ -9,8 +9,9 @@ :refer [columns cross-join do-update-set from full-join group-by having insert-into join left-join limit offset on-conflict order-by + over partition-by returning right-join - select select-distinct values where with]])) + select select-distinct values where window with]])) (deftest test-select (let [m1 (-> (with [:cte (-> (select :*) @@ -305,7 +306,30 @@ " ON CONFLICT (did)" " DO UPDATE SET dname = EXCLUDED.dname || ? || distributors.dname || ?," " downer = EXCLUDED.downer") - 23 "Foo Distributors" " (formerly " ")"]))) + 23 "Foo Distributors" " (formerly " ")"])) + ;; insert into / insert into as tests are below + (is (= (-> (select :id + (over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average] + [[:max :salary] :w :MaxSalary])) + (from :employee) + (window :w (partition-by :department)) + sql/format) + [(str "SELECT id," + " AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average," + " MAX(salary) OVER w AS MaxSalary" + " FROM employee" + " WINDOW w AS (PARTITION BY department)")])) + ;; test nil / empty window function clause: + (is (= (-> (select :id + (over [[:avg :salary] {} :Average] + [[:max :salary] nil :MaxSalary])) + (from :employee) + sql/format) + [(str "SELECT id," + " AVG(salary) OVER () AS Average," + " MAX(salary) OVER () AS MaxSalary" + " FROM employee")])) + ) (deftest issue-293-insert-into-data ;; insert into as (and other tests) based on :insert-into From 83d4ccba38327e389a68657ebfee1005be4d9ceb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 20:07:05 -0800 Subject: [PATCH 129/254] Addresses #293 start work on DDL support --- doc/clause-reference.md | 20 ++++++++++++++++ src/honey/sql.cljc | 40 +++++++++++++++++++++++++++++--- src/honey/sql/helpers.cljc | 5 ++++ test/honey/sql/helpers_test.cljc | 25 ++++++++++++++++---- 4 files changed, 83 insertions(+), 7 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index d0e63fa..22e77a2 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -11,6 +11,26 @@ a space (e.g., `:left-join` is formatted as `LEFT JOIN`). Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. +## alter-table + +## create-table + +## create-view + +## drop-table + +`:drop-table` can accept a single table name or a sequence of +table names. If a sequence is provided and the first element +is `:if-exists` (or the symbol `if-exists`) then that conditional +clause is added before the table names: + +```clojure +user=> (sql/format '{drop-table (if-exists foo bar)}) +["DROP TABLE IF EXISTS foo, bar"] +user=> (sql/format {:drop-table [:foo :bar]}) +["DROP TABLE foo, bar"] +``` + ## nest This is pseudo-syntax that lets you wrap a substatement diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3d4e935..ca768ab 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -36,7 +36,10 @@ (declare clause-format) (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." - [:nest :with :with-recursive :intersect :union :union-all :except :except-all + [;; DDL comes first (these don't really have a precedence): + :alter-table :create-table :with-columns :create-view :drop-table + ;; then SQL clauses in priority order: + :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :insert-into :update :delete :delete-from :truncate :columns :set :from :using :join :left-join :right-join :inner-join :outer-join :full-join @@ -139,7 +142,12 @@ (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) -(defn- format-entity [x & [{:keys [aliased drop-ns]}]] +(defn format-entity + "Given a simple SQL entity (a keyword or symbol -- or string), + return the equivalent SQL fragment (as a string -- no parameters). + + Handles quoting, splitting at / or ., replacing - with _ etc." + [x & [{:keys [aliased drop-ns]}]] (let [nn (if (or *quoted* (string? x)) name name-_) q (if (or *quoted* (string? x)) (:quote *dialect*) identity) [t c] (if-let [n (when-not (or drop-ns (string? x)) @@ -458,6 +466,27 @@ [(str (sql-kw k) " " e " = EXCLUDED." e)]) (format-set-exprs k x))) +(defn- format-alter-table [k [x]] ["ALTER TABLE"]) + +(defn- format-create-table [k table] + (let [[table if-not-exists] (if (sequential? table) table [table])] + [(str (sql-kw k) " " + (when if-not-exists (str (sql-kw :if-not-exists) " ")) + (format-entity table))])) + +(defn- format-create-view [k x] + [(str (sql-kw k) " " (format-entity x) " AS")]) + +(defn- format-drop-table + [k params] + (let [tables (if (sequential? params) params [params]) + [if-exists & tables] (if (#{:if-exists 'if-exists} (first tables)) tables (cons nil tables))] + [(str (sql-kw k) " " + (when if-exists (str (sql-kw :if-exists) " ")) + (str/join ", " (map #'format-entity tables)))])) + +(defn- format-table-columns [k [x]] ["()"]) + (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. @@ -473,7 +502,12 @@ (def ^:private clause-format "The (default) behavior for each known clause. Can also have items added and removed." - (atom {:nest (fn [_ x] (format-expr x)) + (atom {:alter-table #'format-alter-table + :create-table #'format-create-table + :with-columns #'format-table-columns + :create-view #'format-create-view + :drop-table #'format-drop-table + :nest (fn [_ x] (format-expr x)) :with #'format-with :with-recursive #'format-with :intersect #'format-on-set-op diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 4b67300..97c6bfe 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -43,6 +43,11 @@ (assoc data k arg) (assoc {} k data))) +(defn alter-table [& args] (generic :nest args)) +(defn create-table [& args] (generic :nest args)) +(defn with-columns [& args] (generic :nest args)) +(defn create-view [& args] (generic :nest args)) +(defn drop-table [& args] (generic :nest args)) (defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index f3e62c9..cf4ddba 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -6,7 +6,8 @@ :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] [honey.sql.helpers - :refer [columns cross-join do-update-set from full-join + :refer [columns create-view + cross-join do-update-set from full-join group-by having insert-into join left-join limit offset on-conflict order-by over partition-by @@ -278,7 +279,7 @@ " AND (location NOT LIKE '/1/%')")] (stack-overflow-282 2)))) -(deftest issue-293 +(deftest issue-293-sql ;; these tests are based on the README at https://github.com/nilenso/honeysql-postgres (is (= (-> (insert-into :distributors) (values [{:did 5 :dname "Gizmo Transglobal"} @@ -328,8 +329,24 @@ [(str "SELECT id," " AVG(salary) OVER () AS Average," " MAX(salary) OVER () AS MaxSalary" - " FROM employee")])) - ) + " FROM employee")]))) + +(deftest issue-293-ddl + (is (= (sql/format {:create-view :metro :select [:*] :from [:cities] :where [:= :metroflag "y"]}) + ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"])) + (is (= (sql/format {:create-table :films + :with-columns []}) + ["CREATE TABLE films ()"])) + (is (= (sql/format {:drop-table :foo}) + ["DROP TABLE foo"])) + (is (= (sql/format {:drop-table [:if-exists :foo]}) + ["DROP TABLE IF EXISTS foo"])) + (is (= (sql/format '{drop-table (if-exists foo)}) + ["DROP TABLE IF EXISTS foo"])) + (is (= (sql/format {:drop-table [:foo :bar]}) + ["DROP TABLE foo, bar"])) + (is (= (sql/format {:drop-table [:if-exists :foo :bar]}) + ["DROP TABLE IF EXISTS foo, bar"]))) (deftest issue-293-insert-into-data ;; insert into as (and other tests) based on :insert-into From 49d8365bfb06c9e4813e9feb3eb0a847e9a01603 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Wed, 10 Feb 2021 22:32:29 -0800 Subject: [PATCH 130/254] Addresses #293 partial with-columns implementation --- src/honey/sql.cljc | 16 +++++++++++++++- test/honey/sql/helpers_test.cljc | 5 +++-- 2 files changed, 18 insertions(+), 3 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index ca768ab..118274c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -485,7 +485,21 @@ (when if-exists (str (sql-kw :if-exists) " ")) (str/join ", " (map #'format-entity tables)))])) -(defn- format-table-columns [k [x]] ["()"]) +(defn- format-table-columns [k xs] + (let [simple-expr (fn [e] + (let [[x & y] (format-expr e)] + (when (seq y) + (throw (ex-info "column elements must be simple expressions" + {:expr e :params y}))) + x))] + (binding [*inline* true] + [(str "(\n " + (str/join ",\n " + (map #(str/join " " + (let [[id & spec] (map simple-expr %)] + (cons id (map upper-case spec)))) + xs)) + "\n)")]))) (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index cf4ddba..27a9f78 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -335,8 +335,9 @@ (is (= (sql/format {:create-view :metro :select [:*] :from [:cities] :where [:= :metroflag "y"]}) ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"])) (is (= (sql/format {:create-table :films - :with-columns []}) - ["CREATE TABLE films ()"])) + :with-columns [[:id :int :unsigned :auto-increment] + [:name [:varchar 50] [:not nil]]]}) + ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) (is (= (sql/format {:drop-table :foo}) ["DROP TABLE foo"])) (is (= (sql/format {:drop-table [:if-exists :foo]}) From 167d7cee0cf84e5341add8b9acd466e8156ea03f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Feb 2021 17:08:37 -0800 Subject: [PATCH 131/254] Addresses #293 by adding alter table stuff And documenting more of the DDL. --- doc/clause-reference.md | 39 +++++++++++++++++++-- src/honey/sql.cljc | 59 +++++++++++++++++++++++--------- src/honey/sql/helpers.cljc | 16 ++++++--- test/honey/sql/helpers_test.cljc | 52 +++++++++++++++++++++++++--- 4 files changed, 138 insertions(+), 28 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 22e77a2..becbb85 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -11,12 +11,45 @@ a space (e.g., `:left-join` is formatted as `LEFT JOIN`). Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. -## alter-table +## alter-table, add-column, drop-column, modify-column, rename-column -## create-table +## add-index, drop-index + +## create-table, with-columns + +`:create-table` can accept a single table name or a pair +containing a table name and a flag indicating the creation +should be conditional (`:if-not-exists` or the symbol `if-not-exists`, +although any truthy value will work). `:create-table` should +be used with `:with-columns` to specify the actual columns +in the table: + +```clojure +user=> (sql/format {:create-table :fruit + :with-columns + [[:id :int [:not nil]] + [:name [:varchar 32] [:not nil]] + [:cost :float :null]]}) +;; \n has been replaced by an actual newline here for clarity: +["CREATE TABLE fruit ( + id INT NOT NULL, + name VARCHAR(32) NOT NULL, + cost FLOAT NULL +)"] +``` ## create-view +`:create-view` accepts a single view name: + +```clojure +user=> (sql/format {:create-view :products + :select [:*] + :from [:items] + :where [:= :category "product"]}) +["CREATE VIEW products AS SELECT * FROM items WHERE category = ?" "product"] +``` + ## drop-table `:drop-table` can accept a single table name or a sequence of @@ -31,6 +64,8 @@ user=> (sql/format {:drop-table [:foo :bar]}) ["DROP TABLE foo, bar"] ``` +## rename-table + ## nest This is pseudo-syntax that lets you wrap a substatement diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 118274c..43afb9b 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -37,7 +37,9 @@ (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." [;; DDL comes first (these don't really have a precedence): - :alter-table :create-table :with-columns :create-view :drop-table + :alter-table :add-column :drop-column :rename-column + :add-index :drop-index :rename-table + :create-table :with-columns :create-view :drop-table ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :insert-into :update :delete :delete-from :truncate @@ -466,7 +468,19 @@ [(str (sql-kw k) " " e " = EXCLUDED." e)]) (format-set-exprs k x))) -(defn- format-alter-table [k [x]] ["ALTER TABLE"]) +(defn- format-simple-clause [c] + (let [[x & y] (format-dsl c)] + (when (seq y) + (throw (ex-info "column/index operations must be simple clauses" + {:clause c :params y}))) + x)) + +(defn- format-alter-table [k x] + (if (sequential? x) + [(str (sql-kw k) " " (format-entity (first x)) + (when-let [clauses (next x)] + (str " " (str/join ", " (map #'format-simple-clause clauses)))))] + [(str (sql-kw k) " " (format-entity x))])) (defn- format-create-table [k table] (let [[table if-not-exists] (if (sequential? table) table [table])] @@ -485,21 +499,28 @@ (when if-exists (str (sql-kw :if-exists) " ")) (str/join ", " (map #'format-entity tables)))])) +(defn- format-simple-expr [e] + (let [[x & y] (format-expr e)] + (when (seq y) + (throw (ex-info "column elements must be simple expressions" + {:expr e :params y}))) + x)) + +(defn- format-single-column [xs] + (binding [*inline* true] + (str/join " " (let [[id & spec] (map #'format-simple-expr xs)] + (cons id (map upper-case spec)))))) + (defn- format-table-columns [k xs] - (let [simple-expr (fn [e] - (let [[x & y] (format-expr e)] - (when (seq y) - (throw (ex-info "column elements must be simple expressions" - {:expr e :params y}))) - x))] - (binding [*inline* true] - [(str "(\n " - (str/join ",\n " - (map #(str/join " " - (let [[id & spec] (map simple-expr %)] - (cons id (map upper-case spec)))) - xs)) - "\n)")]))) + [(str "(\n " + (str/join ",\n " (map #'format-single-column xs)) + "\n)")]) + +(defn- format-add-item [k spec] + [(str (sql-kw k) " " (format-single-column spec))]) + +(defn- format-rename-item [k [x y]] + [(str (sql-kw k) " " (format-entity x) " TO " (format-entity y))]) (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. @@ -517,6 +538,12 @@ "The (default) behavior for each known clause. Can also have items added and removed." (atom {:alter-table #'format-alter-table + :add-column #'format-add-item + :drop-column #'format-selector + :rename-column #'format-rename-item + :add-index #'format-add-item + :drop-index #'format-selector + :rename-table #'format-rename-item :create-table #'format-create-table :with-columns #'format-table-columns :create-view #'format-create-view diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 97c6bfe..13a2dc4 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -43,11 +43,17 @@ (assoc data k arg) (assoc {} k data))) -(defn alter-table [& args] (generic :nest args)) -(defn create-table [& args] (generic :nest args)) -(defn with-columns [& args] (generic :nest args)) -(defn create-view [& args] (generic :nest args)) -(defn drop-table [& args] (generic :nest args)) +(defn alter-table [& args] (generic :alter-table args)) +(defn add-column [& args] (generic :add-column args)) +(defn drop-column [& args] (generic-1 :drop-column args)) +(defn rename-column [& args] (generic :rename-column args)) +(defn add-index [& args] (generic :add-index args)) +(defn drop-index [& args] (generic-1 :drop-index args)) +(defn rename-table [& args] (generic :alter-table args)) +(defn create-table [& args] (generic :create-table args)) +(defn with-columns [& args] (generic :with-columns args)) +(defn create-view [& args] (generic-1 :create-view args)) +(defn drop-table [& args] (generic :drop-table args)) (defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 27a9f78..34dc372 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -6,13 +6,13 @@ :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] [honey.sql.helpers - :refer [columns create-view - cross-join do-update-set from full-join + :refer [add-column add-index alter-table columns create-table create-view + cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into join left-join limit offset on-conflict order-by over partition-by - returning right-join - select select-distinct values where window with]])) + rename-column rename-table returning right-join + select select-distinct values where window with with-columns]])) (deftest test-select (let [m1 (-> (with [:cte (-> (select :*) @@ -331,13 +331,38 @@ " MAX(salary) OVER () AS MaxSalary" " FROM employee")]))) -(deftest issue-293-ddl +(deftest issue-293-basic-ddl (is (= (sql/format {:create-view :metro :select [:*] :from [:cities] :where [:= :metroflag "y"]}) ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"])) (is (= (sql/format {:create-table :films :with-columns [[:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]]}) ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + (is (= (sql/format (-> (create-view :metro) + (select :*) + (from :cities) + (where [:= :metroflag "y"]))) + ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"])) + (is (= (sql/format (-> (create-table :films) + (with-columns + [:id :int :unsigned :auto-increment] + [:name [:varchar 50] [:not nil]]))) + ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + (is (= (sql/format (-> (create-table :films :if-not-exists) + (with-columns + [:id :int :unsigned :auto-increment] + [:name [:varchar 50] [:not nil]]))) + ["CREATE TABLE IF NOT EXISTS films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + (is (= (sql/format (-> {:create-table :films + :with-columns + [[:id :int :unsigned :auto-increment] + [:name [:varchar 50] [:not nil]]]})) + ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + (is (= (sql/format (-> {:create-table [:films :if-not-exists] + :with-columns + [[:id :int :unsigned :auto-increment] + [:name [:varchar 50] [:not nil]]]})) + ["CREATE TABLE IF NOT EXISTS films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) (is (= (sql/format {:drop-table :foo}) ["DROP TABLE foo"])) (is (= (sql/format {:drop-table [:if-exists :foo]}) @@ -347,8 +372,25 @@ (is (= (sql/format {:drop-table [:foo :bar]}) ["DROP TABLE foo, bar"])) (is (= (sql/format {:drop-table [:if-exists :foo :bar]}) + ["DROP TABLE IF EXISTS foo, bar"])) + (is (= (sql/format (drop-table :foo)) + ["DROP TABLE foo"])) + (is (= (sql/format (drop-table :if-exists :foo)) + ["DROP TABLE IF EXISTS foo"])) + (is (= (sql/format (drop-table :foo :bar)) + ["DROP TABLE foo, bar"])) + (is (= (sql/format (drop-table :if-exists :foo :bar)) ["DROP TABLE IF EXISTS foo, bar"]))) +(deftest issue-293-alter-table + (is (= (sql/format (-> (alter-table :fruit) + (add-column :id :int [:not nil]))) + ["ALTER TABLE fruit ADD COLUMN id INT NOT NULL"])) + (is (= (sql/format (alter-table :fruit + (add-column :id :int [:not nil]) + (drop-column :ident))) + ["ALTER TABLE fruit ADD COLUMN id INT NOT NULL, DROP COLUMN ident"]))) + (deftest issue-293-insert-into-data ;; insert into as (and other tests) based on :insert-into ;; examples in the clause reference docs: From 41ed38ea3847eec215cf4f08f3bd3ac36b72e023 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Feb 2021 21:50:22 -0800 Subject: [PATCH 132/254] Finish and document DDL --- doc/clause-reference.md | 73 +++++++++++++++++++++++++++++++++++++ doc/special-syntax.md | 63 +++++++++++++++++++++++++++++--- src/honey/sql.cljc | 75 ++++++++++++++++++++++++++++---------- src/honey/sql/helpers.cljc | 1 + 4 files changed, 187 insertions(+), 25 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index becbb85..3b9bc5d 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -13,8 +13,62 @@ dialects that HoneySQL supports. ## alter-table, add-column, drop-column, modify-column, rename-column +`:alter-table` can accept either a single table name or +a sequence that begins with a table name and is followed +by clauses that manipulate columns (or indices, see below). + +If a single table name is provided, a single column +(or index) operation can provided in the hash map DSL: + +```clojure +user=> (sql/format {:alter-table :fruit + :add-column [:id :int [:not nil]]}) +["ALTER TABLE fruit ADD COLUMN id INT NOT NULL"] +user=> (sql/format {:alter-table :fruit + :drop-column :ident}) +["ALTER TABLE fruit DROP COLUMN ident"] +user=> (sql/format {:alter-table :fruit + :modify-column [:id :int :unsigned nil]}) +["ALTER TABLE fruit MODIFY COLUMN id INT UNSIGNED NULL"] +user=> (sql/format {:alter-table :fruit + :rename-column [:look :appearance]}) +["ALTER TABLE fruit RENAME COLUMN look TO appearance"] +``` + +If a sequence of a table name and various clauses is +provided, the generated `ALTER` statement will have +comma-separated clauses: + +```clojure +user=> (sql/format {:alter-table [:fruit + {:add-column [:id :int [:not nil]]} + {:drop-column :ident}]}) +["ALTER TABLE fruit ADD COLUMN id INT NOT NULL, DROP COLUMN ident"] +``` + +As can be seen above, `:add-column` and `:modify-column` +both accept a column description (as a sequence of simple +expressions); `:drop-column` accepts a single column name, +and `:rename-column` accepts a sequence with two column +names: the "from" and the "to" names. + ## add-index, drop-index +`:add-index` accepts a single (function) expression +that describes an index, and `:drop-index` accepts a +single index name: + +```clojure +user=> (sql/format {:alter-table :fruit + :add-index [:index :look :appearance]}) +["ALTER TABLE fruit ADD INDEX look(appearance)"] +user=> (sql/format {:alter-table :fruit + :add-index [:unique nil :color :appearance]}) +["ALTER TABLE fruit ADD UNIQUE(color,appearance)"] +user=> (sql/format {:alter-table :fruit :drop-index :look}) +["ALTER TABLE fruit DROP INDEX look"] +``` + ## create-table, with-columns `:create-table` can accept a single table name or a pair @@ -38,6 +92,17 @@ user=> (sql/format {:create-table :fruit )"] ``` +The `:with-columns` clause is formatted as if `{:inline true}` +was specified so nothing is parameterized. In addition, +everything except the first element of a column description +will be uppercased (mostly to give the appearance of separating +the column name from the SQL keywords). + +Various function-like expressions can be specified, as shown +in the example above, but allow things like `CHECK` for a +constraint, `FOREIGN KEY` (with a column name), `REFERENCES` +(with a pair of column names). See [special-syntax.md#clause-descriptors](Clause Descriptors in Special Syntax) for more details. + ## create-view `:create-view` accepts a single view name: @@ -66,6 +131,14 @@ user=> (sql/format {:drop-table [:foo :bar]}) ## rename-table +`:rename-table` accepts a pair of the "from" table name +and the "to" table names: + +```clojure +user=> (sql/format {:rename-table [:fruit :vegetable]}) +["RENAME TABLE fruit TO vegetable"] +``` + ## nest This is pseudo-syntax that lets you wrap a substatement diff --git a/doc/special-syntax.md b/doc/special-syntax.md index df6f088..88e1a24 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -4,6 +4,8 @@ This section lists the function-like expressions that HoneySQL supports out of the box which are formatted as special syntactic forms. +The first group are used for SQL expressions. The second (last group) are used primarily in column definitions (as part of `:with-columns` and `:add-column` / `:modify-column`). + ## array Accepts a single argument, which is expected to evaluate to @@ -58,12 +60,6 @@ expression (comma-separated, wrapped in parentheses): ;;=> ["(a, b, ?, x + ?)" "red" 1] ``` -## default - -Takes no arguments and produces the SQL keyword `DEFAULT`. - -_[I expect this to be expanded for PostgreSQL]_ - ## inline Accepts a single argument and tries to render it as a @@ -186,3 +182,58 @@ parameters from them: (sql/format {:select [:a [[:raw ["@var := " ["foo"]]]]]}) ;;=> ["SELECT a, @var := ?" "foo"] ``` + +## Column Descriptors + +There are three types of descriptors that vary +in how they treat their first argument. All three +descriptors automatically try to inline any parameters +(and will throw an exception if they can't, since these +descriptors are meant to be used in column or index +specifications). + +### foreign-key, primary-key + +If no arguments are provided, these render as just SQL +keywords (uppercase): + +```clojure +[:foreign-key] ;=> FOREIGN KEY +[:primary-key] ;=> PRIMARY KEY +``` + +Otherwise, these render as regular function calls: + +```clojure +[:foreign-key :a] ;=> FOREIGN KEY(a) +[:primary-key :x :y] ;=> PRIMARY KEY(x,y) +``` + +## constraint, default, references + +Although these are grouped together, they are generally +used differently. This group renders as SQL keywords if +no arguments are provided. If a single argument is +provided, this renders as a SQL keyword followed by the +argument. If two or more arguments are provided, this +renders as a SQL keyword followed by the first argument, +followed by the rest as a regular argument list: + +```clojure +[:default] ;=> DEFAULT +[:default 42] ;=> DEFAULT 42 +[:default "str"] ;=> DEFAULT 'str' +[:constraint :name] ;=> CONSTRAINT name +[:references :foo :bar] ;=> REFERENCES foo(bar) +``` + +## index, unique + +These behave like the group above except that if the +first argument is `nil`, it is omitted: + +```clojure +[:index :foo :bar :quux] ;=> INDEX foo(bar,quux) +[:index nil :bar :quux] ;=> INDEX(bar,quux) +[:unique :a :b] ;=> UNIQUE a(b) +``` diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 43afb9b..a378d38 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -37,7 +37,7 @@ (def ^:private default-clause-order "The (default) order for known clauses. Can have items added and removed." [;; DDL comes first (these don't really have a precedence): - :alter-table :add-column :drop-column :rename-column + :alter-table :add-column :drop-column :modify-column :rename-column :add-index :drop-index :rename-table :create-table :with-columns :create-view :drop-table ;; then SQL clauses in priority order: @@ -469,11 +469,12 @@ (format-set-exprs k x))) (defn- format-simple-clause [c] - (let [[x & y] (format-dsl c)] - (when (seq y) - (throw (ex-info "column/index operations must be simple clauses" - {:clause c :params y}))) - x)) + (binding [*inline* true] + (let [[x & y] (format-dsl c)] + (when (seq y) + (throw (ex-info "column/index operations must be simple clauses" + {:clause c :params y}))) + x))) (defn- format-alter-table [k x] (if (sequential? x) @@ -500,16 +501,16 @@ (str/join ", " (map #'format-entity tables)))])) (defn- format-simple-expr [e] - (let [[x & y] (format-expr e)] - (when (seq y) - (throw (ex-info "column elements must be simple expressions" - {:expr e :params y}))) - x)) + (binding [*inline* true] + (let [[x & y] (format-expr e)] + (when (seq y) + (throw (ex-info "column elements must be simple expressions" + {:expr e :params y}))) + x))) (defn- format-single-column [xs] - (binding [*inline* true] - (str/join " " (let [[id & spec] (map #'format-simple-expr xs)] - (cons id (map upper-case spec)))))) + (str/join " " (let [[id & spec] (map #'format-simple-expr xs)] + (cons id (map upper-case spec))))) (defn- format-table-columns [k xs] [(str "(\n " @@ -540,8 +541,10 @@ (atom {:alter-table #'format-alter-table :add-column #'format-add-item :drop-column #'format-selector + :modify-column #'format-add-item :rename-column #'format-rename-item - :add-index #'format-add-item + ;; so :add-index works with both [:index] and [:unique] + :add-index (fn [_ x] (format-on-expr :add x)) :drop-index #'format-selector :rename-table #'format-rename-item :create-table #'format-create-table @@ -676,9 +679,46 @@ (into params-x) (into params-y))))) +(defn- function-0 [k xs] + [(str (sql-kw k) + (when (seq xs) + (str "(" (str/join "," (map #'format-simple-expr xs)) ")")))]) + +(defn- function-1 [k xs] + [(str (sql-kw k) + (when (seq xs) + (str " " (format-simple-expr (first xs)) + (when-let [args (next xs)] + (str "(" (str/join "," (map #'format-simple-expr args)) ")")))))]) + +(defn- function-1-opt [k xs] + [(str (sql-kw k) + (when (seq xs) + (str (when-let [e (first xs)] + (str " " (format-simple-expr e))) + (when-let [args (next xs)] + (str "(" (str/join "," (map #'format-simple-expr args)) ")")))))]) + (def ^:private special-syntax (atom - {:array + {;; these "functions" are mostly used in column + ;; descriptions so they generally have one of two forms: + ;; function-0 - with zero arguments, renders as a keyword, + ;; otherwise renders as a function call + ;; function-1 - with zero arguments, renders as a keyword, + ;; with one argument, as a keyword followed by an entity, + ;; otherwise renders as a keyword followed by a function + ;; call using the first entity as the function + ;; function-1-opt - like function-1 except if the first + ;; argument is nil, it is omitted + :constraint #'function-1 + :default #'function-1 + :foreign-key #'function-0 + :index #'function-1-opt + :primary-key #'function-0 + :references #'function-1 + :unique #'function-1-opt + :array (fn [_ [arr]] (let [[sqls params] (format-expr-list arr)] (into [(str "ARRAY[" (str/join ", " sqls) "]")] params))) @@ -720,9 +760,6 @@ (fn [_ [& args]] (let [[sqls params] (format-expr-list args)] (into [(str "(" (str/join ", " sqls) ")")] params))) - :default - (fn [_ []] - ["DEFAULT"]) :inline (fn [_ [x]] (if (sequential? x) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 13a2dc4..dd727a9 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -46,6 +46,7 @@ (defn alter-table [& args] (generic :alter-table args)) (defn add-column [& args] (generic :add-column args)) (defn drop-column [& args] (generic-1 :drop-column args)) +(defn modify-column [& args] (generic :modify-column args)) (defn rename-column [& args] (generic :rename-column args)) (defn add-index [& args] (generic :add-index args)) (defn drop-index [& args] (generic-1 :drop-index args)) From 4b7ded4009b3014615582442bb4bce0fda6d4b6f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 10:50:36 -0800 Subject: [PATCH 133/254] WIP nilenso test (fails) --- doc/clause-reference.md | 2 +- doc/special-syntax.md | 6 +- src/honey/sql.cljc | 13 +- src/honey/sql/helpers.cljc | 15 +- test/honey/sql/helpers_test.cljc | 10 +- test/honey/sql/postgres_test.cljc | 304 ++++++++++++++++++++++++++++++ 6 files changed, 333 insertions(+), 17 deletions(-) create mode 100644 test/honey/sql/postgres_test.cljc diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 3b9bc5d..a9a1f0e 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -84,7 +84,7 @@ user=> (sql/format {:create-table :fruit [[:id :int [:not nil]] [:name [:varchar 32] [:not nil]] [:cost :float :null]]}) -;; \n has been replaced by an actual newline here for clarity: +;; reformatted for clarity: ["CREATE TABLE fruit ( id INT NOT NULL, name VARCHAR(32) NOT NULL, diff --git a/doc/special-syntax.md b/doc/special-syntax.md index 88e1a24..f75a6cf 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -206,7 +206,7 @@ Otherwise, these render as regular function calls: ```clojure [:foreign-key :a] ;=> FOREIGN KEY(a) -[:primary-key :x :y] ;=> PRIMARY KEY(x,y) +[:primary-key :x :y] ;=> PRIMARY KEY(x, y) ``` ## constraint, default, references @@ -233,7 +233,7 @@ These behave like the group above except that if the first argument is `nil`, it is omitted: ```clojure -[:index :foo :bar :quux] ;=> INDEX foo(bar,quux) -[:index nil :bar :quux] ;=> INDEX(bar,quux) +[:index :foo :bar :quux] ;=> INDEX foo(bar, quux) +[:index nil :bar :quux] ;=> INDEX(bar, quux) [:unique :a :b] ;=> UNIQUE a(b) ``` diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a378d38..a6d223d 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -513,9 +513,9 @@ (cons id (map upper-case spec))))) (defn- format-table-columns [k xs] - [(str "(\n " - (str/join ",\n " (map #'format-single-column xs)) - "\n)")]) + [(str "(" + (str/join ", " (map #'format-single-column xs)) + ")")]) (defn- format-add-item [k spec] [(str (sql-kw k) " " (format-single-column spec))]) @@ -682,14 +682,14 @@ (defn- function-0 [k xs] [(str (sql-kw k) (when (seq xs) - (str "(" (str/join "," (map #'format-simple-expr xs)) ")")))]) + (str "(" (str/join ", " (map #'format-simple-expr xs)) ")")))]) (defn- function-1 [k xs] [(str (sql-kw k) (when (seq xs) (str " " (format-simple-expr (first xs)) (when-let [args (next xs)] - (str "(" (str/join "," (map #'format-simple-expr args)) ")")))))]) + (str "(" (str/join ", " (map #'format-simple-expr args)) ")")))))]) (defn- function-1-opt [k xs] [(str (sql-kw k) @@ -697,7 +697,7 @@ (str (when-let [e (first xs)] (str " " (format-simple-expr e))) (when-let [args (next xs)] - (str "(" (str/join "," (map #'format-simple-expr args)) ")")))))]) + (str "(" (str/join ", " (map #'format-simple-expr args)) ")")))))]) (def ^:private special-syntax (atom @@ -1007,6 +1007,7 @@ (format-expr :id) (format-expr 1) (format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) + (format {:select [[[:d :e]] :a [:b :c]]}) (format-on-expr :where [:= :id 1]) (format-dsl {:select [:*] :from [:table] :where [:= :id 1]}) (format {:select [:t.*] :from [[:table :t]] :where [:= :id 1]} {}) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index dd727a9..100382c 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -52,7 +52,15 @@ (defn drop-index [& args] (generic-1 :drop-index args)) (defn rename-table [& args] (generic :alter-table args)) (defn create-table [& args] (generic :create-table args)) -(defn with-columns [& args] (generic :with-columns args)) +(defn with-columns [& args] + ;; special case so (with-columns [[:col-1 :definition] [:col-2 :definition]]) + ;; also works in addition to (with-columns [:col-1 :definition] [:col-2 :definition]) + (cond (and (= 1 (count args)) (sequential? (first args)) (sequential? (ffirst args))) + (generic-1 :with-columns args) + (and (= 2 (count args)) (sequential? (second args)) (sequential? (fnext args))) + (generic-1 :with-columns args) + :else + (generic :with-columns args))) (defn create-view [& args] (generic-1 :create-view args)) (defn drop-table [& args] (generic :drop-table args)) (defn nest [& args] (generic :nest args)) @@ -105,7 +113,10 @@ ;; to make this easy to use in a select, wrap it so it becomes a function: (defn over [& args] [(into [:over] args)]) +;; helper to ease compatibility with former nilenso/honeysql-postgres code: +(defn upsert [data & clauses] (default-merge data clauses)) + #?(:clj (assert (= (clojure.core/set (conj @@#'h/base-clause-order - :composite :over)) + :composite :over :upsert)) (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 34dc372..a5c251c 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -337,7 +337,7 @@ (is (= (sql/format {:create-table :films :with-columns [[:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]]}) - ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + ["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"])) (is (= (sql/format (-> (create-view :metro) (select :*) (from :cities) @@ -347,22 +347,22 @@ (with-columns [:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]))) - ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + ["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"])) (is (= (sql/format (-> (create-table :films :if-not-exists) (with-columns [:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]))) - ["CREATE TABLE IF NOT EXISTS films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + ["CREATE TABLE IF NOT EXISTS films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"])) (is (= (sql/format (-> {:create-table :films :with-columns [[:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]]})) - ["CREATE TABLE films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + ["CREATE TABLE films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"])) (is (= (sql/format (-> {:create-table [:films :if-not-exists] :with-columns [[:id :int :unsigned :auto-increment] [:name [:varchar 50] [:not nil]]]})) - ["CREATE TABLE IF NOT EXISTS films (\n id INT UNSIGNED AUTO_INCREMENT,\n name VARCHAR(50) NOT NULL\n)"])) + ["CREATE TABLE IF NOT EXISTS films (id INT UNSIGNED AUTO_INCREMENT, name VARCHAR(50) NOT NULL)"])) (is (= (sql/format {:drop-table :foo}) ["DROP TABLE foo"])) (is (= (sql/format {:drop-table [:if-exists :foo]}) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc new file mode 100644 index 0000000..c720eb8 --- /dev/null +++ b/test/honey/sql/postgres_test.cljc @@ -0,0 +1,304 @@ +;; copied from https://github.com/nilenso/honeysql-postgres +;; on 2021-02-13 to verify the completeness of support for +;; those features within HoneySQL v2 + +;; where there are differences, the original code is kept +;; with #_ and the modified code follows it (aside from +;; the ns form which has numerous changes to both match +;; the structure of HoneySQL v2 and to work with cljs) + +(ns honey.sql.postgres-test + (:refer-clojure :exclude [update partition-by set]) + (:require #?(:clj [clojure.test :refer [deftest is testing]] + :cljs [cljs.test :refer-macros [deftest is testing]]) + ;; pull in all the PostgreSQL helpers that the nilenso + ;; library provided (as well as the regular HoneySQL ones): + [honey.sql.helpers :as sqlh :refer + [upsert on-conflict do-nothing on-constraint + returning do-update-set + ;; not needed because do-update-set can do this directly + #_do-update-set! + alter-table rename-column drop-column + add-column partition-by + ;; not needed because insert-into can do this directly + #_insert-into-as + create-table rename-table drop-table + window create-view over with-columns + ;; temporarily disable until these are also implemented: + #_#_create-extension drop-extension + ;; already part of HoneySQL + insert-into values where select columns + from order-by update set]] + [honey.sql :as sql])) + +(deftest upsert-test + (testing "upsert sql generation for postgresql" + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + (-> (insert-into :distributors) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (upsert (-> (on-conflict :did) + (do-update-set :dname))) + (returning :*) + sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] + (-> (insert-into :distributors) + (values [{:did 7 :dname "Redline GmbH"}]) + (upsert (-> (on-conflict :did) + do-nothing)) + sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + (upsert (-> #_(on-conflict-constraint :distributors_pkey) + (on-conflict (on-constraint :distributors_pkey)) + do-nothing)) + sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname" 10 "Pinp Design" 11 "Foo Bar Works"] + (sql/format {:insert-into :distributors + :values [{:did 10 :dname "Pinp Design"} + {:did 11 :dname "Foo Bar Works"}] + :upsert {:on-conflict [:did] + :do-update-set [:dname]}}))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO UPDATE SET dname = ?" 23 "Foo Distributors" " (formerly " ")"] + (-> (insert-into :distributors) + (values [{:did 23 :dname "Foo Distributors"}]) + (on-conflict :did) + #_(do-update-set! [:dname "EXCLUDED.dname || ' (formerly ' || d.dname || ')'"]) + (do-update-set {:dname [:|| :EXCLUDED.dname " (formerly " :d.dname ")"]}) + sql/format))) + (is (= ["INSERT INTO distributors (did, dname) (SELECT ?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 1 "whatever"] + (-> (insert-into :distributors) + (columns :did :dname) + (select 1 "whatever") + #_(query-values (select 1 "whatever")) + (upsert (-> (on-conflict (on-constraint :distributors_pkey)) + do-nothing)) + sql/format))))) + +(deftest upsert-where-test + (is (= ["INSERT INTO user (phone, name) VALUES (?, ?) ON CONFLICT (phone) WHERE phone IS NOT NULL DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE" "5555555" "John"] + (sql/format + {:insert-into :user + :values [{:phone "5555555" :name "John"}] + :upsert {:on-conflict [:phone] + :where [:<> :phone nil] + :do-update-set {:fields [:phone :name] + :where [:= :user.active false]}}})))) + +(deftest returning-test + (testing "returning clause in sql generation for postgresql" + (is (= ["DELETE FROM distributors WHERE did > 10 RETURNING *"] + (sql/format {:delete-from :distributors + :where [:> :did :10] + :returning [:*]}))) + (is (= ["UPDATE distributors SET dname = ? WHERE did = 2 RETURNING did dname" "Foo Bar Designs"] + (-> (update :distributors) + (set {:dname "Foo Bar Designs"}) + (where [:= :did :2]) + (returning [:did :dname]) + sql/format))))) + +(deftest create-view-test + (testing "creating a view from a table" + (is (= ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "Y"] + (-> (create-view :metro) + (select :*) + (from :cities) + (where [:= :metroflag "Y"]) + sql/format))))) + +(deftest drop-table-test + (testing "drop table sql generation for a single table" + (is (= ["DROP TABLE cities"] + (sql/format (drop-table :cities))))) + (testing "drop table sql generation for multiple tables" + (is (= ["DROP TABLE cities, towns, vilages"] + (sql/format (drop-table :cities :towns :vilages)))))) + +(deftest create-table-test + (testing "create table with two columns" + (is (= ["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"] + (-> (create-table :cities) + (with-columns [[:city [:varchar 80] [:primary-key]] + [:location :point]]) + sql/format)))) + (testing "create table with foreign key reference" + (is (= ["CREATE TABLE weather (city VARCHAR(80) REFERENCES CITIES(CITY), temp_lo INT, temp_hi INT, prcp REAL, date DATE)"] + (-> (create-table :weather) + (with-columns [[:city [:varchar :80] [:references :cities :city]] + [:temp_lo :int] + [:temp_hi :int] + [:prcp :real] + [:date :date]]) + sql/format)))) + (testing "creating table with table level constraint" + (is (= ["CREATE TABLE films (code CHAR(5), title VARCHAR(40), did INTEGER, date_prod DATE, kind VARCHAR(10), CONSTRAINT code_title PRIMARY KEY(CODE, TITLE))"] + (-> (create-table :films) + (with-columns [[:code [:char 5]] + [:title [:varchar 40]] + [:did :integer] + [:date_prod :date] + [:kind [:varchar 10]] + [[:constraint :code_title] [:primary-key :code :title]]]) + sql/format)))) + (testing "creating table with column level constraint" + (is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT firstkey PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"] + (-> (create-table :films) + (with-columns [[:code [:char 5] [:constraint :firstkey] [:primary-key]] + [:title [:varchar 40] [:not nil]] + [:did :integer [:not nil]] + [:date_prod :date] + [:kind [:varchar 10]]]) + sql/format)))) + (testing "creating table with columns with default values" + (is (= ["CREATE TABLE distributors (did INTEGER PRIMARY KEY DEFAULT NEXTVAL('SERIAL'), name VARCHAR(40) NOT NULL)"] + (-> (create-table :distributors) + (with-columns [[:did :integer [:primary-key] [:default [:nextval "serial"]]] + [:name [:varchar 40] [:not nil]]]) + sql/format)))) + (testing "creating table with column checks" + (is (= ["CREATE TABLE products (product_no INTEGER, name TEXT, price NUMERIC CHECK(PRICE > 0), discounted_price NUMERIC, CHECK((discounted_price > 0) AND (price > discounted_price)))"] + (-> (create-table :products) + (with-columns [[:product_no :integer] + [:name :text] + [:price :numeric [:check [:> :price 0]]] + [:discounted_price :numeric] + [[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]]) + sql/format))))) + +(deftest over-test + (testing "window function over on select statemt" + (is (= ["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation) AS Average, max(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] + (-> (select :id) + (over + [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] + [[:max :salary] :w :MaxSalary]) + (from :employee) + (window :w (partition-by :department)) + sql/format))))) + +(deftest alter-table-test + (testing "alter table add column generates the required sql" + (is (= ["ALTER TABLE employees ADD COLUMN address text"] + (-> (alter-table :employees) + (add-column :address :text) + sql/format)))) + (testing "alter table drop column generates the required sql" + (is (= ["ALTER TABLE employees DROP COLUMN address"] + (-> (alter-table :employees) + (drop-column :address) + sql/format)))) + (testing "alter table rename column generates the requred sql" + (is (= ["ALTER TABLE employees RENAME COLUMN address TO homeaddress"] + (-> (alter-table :employees) + (rename-column :address :homeaddress) + sql/format)))) + (testing "alter table rename table generates the required sql" + (is (= ["ALTER TABLE employees RENAME TO managers"] + (-> (alter-table :employees) + (rename-table :managers) + sql/format))))) + +(deftest insert-into-with-alias + (testing "insert into with alias" + (is (= ["INSERT INTO distributors AS d (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname WHERE d.zipcode <> ? RETURNING d.*" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc" "21201"] + (-> #_(insert-into-as :distributors :d) + (insert-into :distributors :d) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (upsert (-> (on-conflict :did) + (do-update-set :dname) + (where [:<> :d.zipcode "21201"]))) + (returning :d.*) + sql/format))))) + +(deftest create-table-if-not-exists + (testing "create a table if not exists" + (is (= ["CREATE TABLE IF NOT EXISTS tablename"] + (-> (create-table :tablename :if-not-exists) + sql/format))))) + +(deftest drop-table-if-exists + (testing "drop a table if it exists" + (is (= ["DROP TABLE IF EXISTS t1, t2, t3"] + (-> (drop-table :if-exists :t1 :t2 :t3) + sql/format))))) + +(deftest select-where-ilike + (testing "select from table with ILIKE operator" + (is (= ["SELECT * FROM products WHERE name ILIKE ?" "%name%"] + (-> (select :*) + (from :products) + (where [:ilike :name "%name%"]) + sql/format))))) + +(deftest select-where-not-ilike + (testing "select from table with NOT ILIKE operator" + (is (= ["SELECT * FROM products WHERE name NOT ILIKE ?" "%name%"] + (-> (select :*) + (from :products) + (where [:not-ilike :name "%name%"]) + sql/format))))) + +(deftest values-except-select + (testing "select which values are not not present in a table" + (is (= ["VALUES (?), (?), (?) EXCEPT SELECT id FROM images" 4 5 6] + (sql/format + {:except + [{:values [[4] [5] [6]]} + {:select [:id] :from [:images]}]}))))) + +(deftest select-except-select + (testing "select which rows are not present in another table" + (is (= ["SELECT ip EXCEPT SELECT ip FROM ip_location"] + (sql/format + {:except + [{:select [:ip]} + {:select [:ip] :from [:ip_location]}]}))))) + +(deftest values-except-all-select + (testing "select which values are not not present in a table" + (is (= ["VALUES (?), (?), (?) EXCEPT ALL SELECT id FROM images" 4 5 6] + (sql/format + {:except-all + [{:values [[4] [5] [6]]} + {:select [:id] :from [:images]}]}))))) + +(deftest select-except-all-select + (testing "select which rows are not present in another table" + (is (= ["SELECT ip EXCEPT ALL SELECT ip FROM ip_location"] + (sql/format + {:except-all + [{:select [:ip]} + {:select [:ip] :from [:ip_location]}]}))))) + +(deftest select-distinct-on + (testing "select distinct on" + (is (= ["SELECT DISTINCT ON(\"a\", \"b\") \"c\" FROM \"products\""] + (-> (select [[:distinct-on :a :b]] :c) + (from :products) + (sql/format {:quoted true})) + #_(-> (select :c) + (from :products) + (modifiers :distinct-on :a :b) + (sql/format :quoting :ansi)))))) + +#_(deftest create-extension-test + (testing "create extension" + (is (= ["CREATE EXTENSION \"uuid-ossp\""] + (-> (create-extension :uuid-ossp) + (sql/format :allow-dashed-names? true + :quoting :ansi))))) + (testing "create extension if not exists" + (is (= ["CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\""] + (-> (create-extension :uuid-ossp :if-not-exists? true) + (sql/format :allow-dashed-names? true + :quoting :ansi)))))) + +#_(deftest drop-extension-test + (testing "create extension" + (is (= ["DROP EXTENSION \"uuid-ossp\""] + (-> (drop-extension :uuid-ossp) + (sql/format :allow-dashed-names? true + :quoting :ansi)))))) From 4ce56997c9a540795bd52e87790a72aeaa4544ba Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 12:24:21 -0800 Subject: [PATCH 134/254] Fix rename table --- doc/clause-reference.md | 23 +++++++++++++---------- src/honey/sql.cljc | 2 +- src/honey/sql/helpers.cljc | 2 +- 3 files changed, 15 insertions(+), 12 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index a9a1f0e..f59bf2e 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -54,6 +54,7 @@ names: the "from" and the "to" names. ## add-index, drop-index +Used with `:alter-table`, `:add-index` accepts a single (function) expression that describes an index, and `:drop-index` accepts a single index name: @@ -69,6 +70,18 @@ user=> (sql/format {:alter-table :fruit :drop-index :look}) ["ALTER TABLE fruit DROP INDEX look"] ``` +## rename-table + +Used with `:alter-table`, +`:rename-table` accepts a single table name: + +```clojure +user=> (sql/format {:alter-table :fruit :rename-table :vegetable}) +["ALTER TABLE fruit RENAME TO vegetable"] +``` + +> Note: this would be better as `:rename-to` since there is a `RENAME TABLE old_name TO new_name` SQL statement. _[I may yet add a variant to support that specifically]_ + ## create-table, with-columns `:create-table` can accept a single table name or a pair @@ -129,16 +142,6 @@ user=> (sql/format {:drop-table [:foo :bar]}) ["DROP TABLE foo, bar"] ``` -## rename-table - -`:rename-table` accepts a pair of the "from" table name -and the "to" table names: - -```clojure -user=> (sql/format {:rename-table [:fruit :vegetable]}) -["RENAME TABLE fruit TO vegetable"] -``` - ## nest This is pseudo-syntax that lets you wrap a substatement diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a6d223d..35e7587 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -546,7 +546,7 @@ ;; so :add-index works with both [:index] and [:unique] :add-index (fn [_ x] (format-on-expr :add x)) :drop-index #'format-selector - :rename-table #'format-rename-item + :rename-table (fn [_ x] (format-selector :rename-to x)) :create-table #'format-create-table :with-columns #'format-table-columns :create-view #'format-create-view diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 100382c..172681a 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -50,7 +50,7 @@ (defn rename-column [& args] (generic :rename-column args)) (defn add-index [& args] (generic :add-index args)) (defn drop-index [& args] (generic-1 :drop-index args)) -(defn rename-table [& args] (generic :alter-table args)) +(defn rename-table [& args] (generic-1 :rename-table args)) (defn create-table [& args] (generic :create-table args)) (defn with-columns [& args] ;; special case so (with-columns [[:col-1 :definition] [:col-2 :definition]]) From f6975ef6bd0e571b24aac719182d26622fa817ed Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 15:58:56 -0800 Subject: [PATCH 135/254] Fix select as, select distinct on --- README.md | 2 +- src/honey/sql.cljc | 77 ++++++++++++++++++++++++++------ src/honey/sql/helpers.cljc | 1 + test/honey/sql/helpers_test.cljc | 4 +- 4 files changed, 68 insertions(+), 16 deletions(-) diff --git a/README.md b/README.md index 42e5372..0541838 100644 --- a/README.md +++ b/README.md @@ -559,7 +559,7 @@ big-complicated-map {:params {:param1 "gabba" :param2 2} :pretty true}) => [" -SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 +SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 35e7587..719f9aa 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -42,7 +42,8 @@ :create-table :with-columns :create-view :drop-table ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all - :select :select-distinct :insert-into :update :delete :delete-from :truncate + :select :select-distinct :select-distinct-on + :insert-into :update :delete :delete-from :truncate :columns :set :from :using :join :left-join :right-join :inner-join :outer-join :full-join :cross-join @@ -272,16 +273,35 @@ (let [[sqls params] (format-expr-list xs {:drop-ns (= :columns k)})] (into [(str "(" (str/join ", " sqls) ")")] params))) -(defn- format-selects [k xs] +(defn- format-selects-common [prefix as xs] (if (sequential? xs) (let [[sqls params] (reduce (fn [[sql params] [sql' & params']] [(conj sql sql') (if params' (into params params') params)]) [[] []] - (map #(format-selectable-dsl % {:as (#{:select :from :window} k)}) xs))] - (into [(str (sql-kw k) " " (str/join ", " sqls))] params)) - (let [[sql & params] (format-selectable-dsl xs {:as (#{:select :from} k)})] - (into [(str (sql-kw k) " " sql)] params)))) + (map #(format-selectable-dsl % {:as as}) xs))] + (into [(str prefix " " (str/join ", " sqls))] params)) + (let [[sql & params] (format-selectable-dsl xs {:as as})] + (into [(str prefix " " sql)] params)))) + +(defn- format-selects [k xs] + (format-selects-common + (sql-kw k) + (#{:select :select-distinct :from :window + 'select 'select-distinct 'from 'window} + k) + xs)) + +(defn- format-selects-on [k xs] + (let [[on & cols] xs + [sql & params] + (format-expr (into [:distinct-on] on)) + [sql' & params'] + (format-selects-common + (str (sql-kw :select) " " sql) + true + cols)] + (-> [sql'] (into params) (into params')))) (defn- format-with-part [x] (if (sequential? x) @@ -457,16 +477,46 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-on-conflict [k x] - (if (or (keyword? x) (symbol? x)) - [(str (sql-kw k) " (" (format-entity x) ")")] - (let [[sql & params] (format-dsl x)] - (into [(str (sql-kw k) " " sql)] params)))) + (cond (or (keyword? x) (symbol? x)) + [(str (sql-kw k) " (" (format-entity x) ")")] + (map? x) + (let [[sql & params] (format-dsl x)] + (into [(str (sql-kw k) " " sql)] params)) + (and (sequential? x) + (or (keyword? (first x)) (symbol? (first x))) + (map? (second x))) + (let [[sql & params] (format-dsl (second x))] + (into [(str (sql-kw k) + " (" (format-entity (first x)) ") " + sql)] + params)) + :else + (throw (ex-info "unsupported :on-conflict format" + {:clause x})))) +(comment + keyword/symbol -> e = excluded.e + [k/s] -> join , e = excluded.e + {e v} -> join , e = v + {:fields f :where w} -> join , e = excluded.e (from f) where w + ,) (defn- format-do-update-set [k x] - (if (or (keyword? x) (symbol? x)) + (if (map? x) + (if (and (or (contains? x :fields) (contains? x 'fields)) + (or (contains? x :where) (contains? x 'where))) + (let [sets (str/join ", " + (map (fn [e] + (let [e (format-entity e {:drop-ns true})] + (str e " = EXCLUDED." e))) + (or (:fields x) + ('fields x)))) + [sql & params] (format-dsl {:where + (or (:where x) + ('where x))})] + (into [(str (sql-kw k) " " sets " " sql)] params)) + (format-set-exprs k x)) (let [e (format-entity x {:drop-ns true})] - [(str (sql-kw k) " " e " = EXCLUDED." e)]) - (format-set-exprs k x))) + [(str (sql-kw k) " " e " = EXCLUDED." e)]))) (defn- format-simple-clause [c] (binding [*inline* true] @@ -561,6 +611,7 @@ :except-all #'format-on-set-op :select #'format-selects :select-distinct #'format-selects + :select-distinct-on #'format-selects-on :insert-into #'format-insert :update #'format-selector :delete #'format-selects diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 172681a..a852f39 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -76,6 +76,7 @@ (defn select [& args] (generic :select args)) (defn select-distinct [& args] (generic :select-distinct args)) +(defn select-distinct-on [& args] (generic :select-distinct-on args)) (defn insert-into [& args] (generic :insert-into args)) (defn update [& args] (generic :update args)) (defn delete [& args] (generic-1 :delete args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index a5c251c..b1063d5 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -58,7 +58,7 @@ (testing "Various construction methods are consistent" (is (= m1 m2))) (testing "SQL data formats correctly" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) #?(:clj (testing "SQL data prints and reads correctly" @@ -68,7 +68,7 @@ ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) (testing "Locking" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] (sql/format (assoc m1 :lock [:in-share-mode]) {:params {:param1 "gabba" :param2 2} From 7b928fecb2d50bd284f5a4c80c8fc4220190e657 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 16:02:13 -0800 Subject: [PATCH 136/254] Addresses #293 by porting nilenso tests I intended to keep all the original tests inline but it got harder than I expected, so I'm going to make another pass over this and insert the original tests back in later. --- test/honey/sql/postgres_test.cljc | 90 +++++++++++++++++-------------- 1 file changed, 51 insertions(+), 39 deletions(-) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index c720eb8..98a745e 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -14,7 +14,9 @@ ;; pull in all the PostgreSQL helpers that the nilenso ;; library provided (as well as the regular HoneySQL ones): [honey.sql.helpers :as sqlh :refer - [upsert on-conflict do-nothing on-constraint + [;; not needed because on-conflict accepts clauses + #_upsert + on-conflict do-nothing on-constraint returning do-update-set ;; not needed because do-update-set can do this directly #_do-update-set! @@ -26,8 +28,9 @@ window create-view over with-columns ;; temporarily disable until these are also implemented: #_#_create-extension drop-extension + select-distinct-on ;; already part of HoneySQL - insert-into values where select columns + insert-into values where select from order-by update set]] [honey.sql :as sql])) @@ -37,43 +40,41 @@ (-> (insert-into :distributors) (values [{:did 5 :dname "Gizmo Transglobal"} {:did 6 :dname "Associated Computing, Inc"}]) - (upsert (-> (on-conflict :did) - (do-update-set :dname))) + (on-conflict :did) + (do-update-set :dname) (returning :*) sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) - (upsert (-> (on-conflict :did) - do-nothing)) + (on-conflict :did) + do-nothing sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) - (upsert (-> #_(on-conflict-constraint :distributors_pkey) - (on-conflict (on-constraint :distributors_pkey)) - do-nothing)) + (on-conflict (on-constraint :distributors_pkey)) + do-nothing sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname" 10 "Pinp Design" 11 "Foo Bar Works"] (sql/format {:insert-into :distributors :values [{:did 10 :dname "Pinp Design"} {:did 11 :dname "Foo Bar Works"}] - :upsert {:on-conflict [:did] - :do-update-set [:dname]}}))) - (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO UPDATE SET dname = ?" 23 "Foo Distributors" " (formerly " ")"] + :on-conflict :did + :do-update-set :dname}))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname || ? || d.dname || ?" 23 "Foo Distributors" " (formerly " ")"] (-> (insert-into :distributors) (values [{:did 23 :dname "Foo Distributors"}]) (on-conflict :did) #_(do-update-set! [:dname "EXCLUDED.dname || ' (formerly ' || d.dname || ')'"]) (do-update-set {:dname [:|| :EXCLUDED.dname " (formerly " :d.dname ")"]}) sql/format))) - (is (= ["INSERT INTO distributors (did, dname) (SELECT ?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 1 "whatever"] - (-> (insert-into :distributors) - (columns :did :dname) - (select 1 "whatever") + (is (= ["INSERT INTO distributors (did, dname) SELECT ?, ? ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 1 "whatever"] + (-> (insert-into [:distributors [:did :dname]] + (select 1 "whatever")) #_(query-values (select 1 "whatever")) - (upsert (-> (on-conflict (on-constraint :distributors_pkey)) - do-nothing)) + (on-conflict (on-constraint :distributors_pkey)) + do-nothing sql/format))))) (deftest upsert-where-test @@ -81,10 +82,10 @@ (sql/format {:insert-into :user :values [{:phone "5555555" :name "John"}] - :upsert {:on-conflict [:phone] - :where [:<> :phone nil] - :do-update-set {:fields [:phone :name] - :where [:= :user.active false]}}})))) + :on-conflict [:phone + {:where [:<> :phone nil]}] + :do-update-set {:fields [:phone :name] + :where [:= :user.active false]}})))) (deftest returning-test (testing "returning clause in sql generation for postgresql" @@ -143,7 +144,7 @@ [[:constraint :code_title] [:primary-key :code :title]]]) sql/format)))) (testing "creating table with column level constraint" - (is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT firstkey PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"] + (is (= ["CREATE TABLE films (code CHAR(5) CONSTRAINT FIRSTKEY PRIMARY KEY, title VARCHAR(40) NOT NULL, did INTEGER NOT NULL, date_prod DATE, kind VARCHAR(10))"] (-> (create-table :films) (with-columns [[:code [:char 5] [:constraint :firstkey] [:primary-key]] [:title [:varchar 40] [:not nil]] @@ -169,18 +170,26 @@ (deftest over-test (testing "window function over on select statemt" - (is (= ["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation) AS Average, max(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] - (-> (select :id) - (over - [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] - [[:max :salary] :w :MaxSalary]) + (is (= ["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] + (-> (select :id + ;; honeysql treats over as a function: + (over + [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] + [[:max :salary] :w :MaxSalary])) (from :employee) (window :w (partition-by :department)) - sql/format))))) + sql/format) + #_(-> (select :id) + (over + [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] + [[:max :salary] :w :MaxSalary]) + (from :employee) + (window :w (partition-by :department)) + sql/format))))) (deftest alter-table-test (testing "alter table add column generates the required sql" - (is (= ["ALTER TABLE employees ADD COLUMN address text"] + (is (= ["ALTER TABLE employees ADD COLUMN address TEXT"] (-> (alter-table :employees) (add-column :address :text) sql/format)))) @@ -207,9 +216,12 @@ (insert-into :distributors :d) (values [{:did 5 :dname "Gizmo Transglobal"} {:did 6 :dname "Associated Computing, Inc"}]) - (upsert (-> (on-conflict :did) - (do-update-set :dname) - (where [:<> :d.zipcode "21201"]))) + (on-conflict :did) + (do-update-set (-> {:fields [:dname]} + (where [:<> :d.zipcode "21201"]))) + #_(upsert (-> (on-conflict :did) + (do-update-set :dname) + (where [:<> :d.zipcode "21201"]))) (returning :d.*) sql/format))))) @@ -243,7 +255,7 @@ (deftest values-except-select (testing "select which values are not not present in a table" - (is (= ["VALUES (?), (?), (?) EXCEPT SELECT id FROM images" 4 5 6] + (is (= ["(VALUES (?), (?), (?)) EXCEPT (SELECT id FROM images)" 4 5 6] (sql/format {:except [{:values [[4] [5] [6]]} @@ -251,7 +263,7 @@ (deftest select-except-select (testing "select which rows are not present in another table" - (is (= ["SELECT ip EXCEPT SELECT ip FROM ip_location"] + (is (= ["(SELECT ip) EXCEPT (SELECT ip FROM ip_location)"] (sql/format {:except [{:select [:ip]} @@ -259,7 +271,7 @@ (deftest values-except-all-select (testing "select which values are not not present in a table" - (is (= ["VALUES (?), (?), (?) EXCEPT ALL SELECT id FROM images" 4 5 6] + (is (= ["(VALUES (?), (?), (?)) EXCEPT ALL (SELECT id FROM images)" 4 5 6] (sql/format {:except-all [{:values [[4] [5] [6]]} @@ -267,16 +279,16 @@ (deftest select-except-all-select (testing "select which rows are not present in another table" - (is (= ["SELECT ip EXCEPT ALL SELECT ip FROM ip_location"] + (is (= ["(SELECT ip) EXCEPT ALL (SELECT ip FROM ip_location)"] (sql/format {:except-all [{:select [:ip]} {:select [:ip] :from [:ip_location]}]}))))) -(deftest select-distinct-on +(deftest select-distinct-on-test (testing "select distinct on" (is (= ["SELECT DISTINCT ON(\"a\", \"b\") \"c\" FROM \"products\""] - (-> (select [[:distinct-on :a :b]] :c) + (-> (select-distinct-on [:a :b] :c) (from :products) (sql/format {:quoted true})) #_(-> (select :c) From 6355452102ec5bc5ab806ee1ab4f55e057235c1a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 16:17:30 -0800 Subject: [PATCH 137/254] Update docs for the PG extension stuff --- doc/clause-reference.md | 41 ++++++++++++++++++++++++++++++++++------- src/honey/sql.cljc | 6 ------ 2 files changed, 34 insertions(+), 13 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index f59bf2e..c53099f 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -204,7 +204,7 @@ user=> (sql/format '{union [{select (id,status) from (table-a)} ## select, select-distinct -`:select` expects a sequence of SQL entities (column names +`:select` and `:select-distinct` expect a sequence of SQL entities (column names or expressions). Any of the SQL entities can be a pair of entity and alias. If you are selecting an expression, you would most often provide an alias for the expression, but it can be omitted as in the following: @@ -228,6 +228,19 @@ user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]] HoneySQL does not yet support `SELECT .. INTO ..` or `SELECT .. BULK COLLECT INTO ..`. +## select-distinct-on + +Similar to `:select-distinct` above but the first element +in the sequence should be a sequence of columns for the +`DISTINCT ON` clause and the remaining elements are the +columns to be selected: + +```clojure +user=> (sql/format '{select-distinct-on [[a b] c d] + from [table]}) +["SELECT DISTINCT ON(a, b) c, d FROM table"] +``` + ## insert-into There are three use cases with `:insert-into`. @@ -615,9 +628,10 @@ as if they are separate clauses but they will appear in pairs: `ON ... DO ...`. `:on-conflict` accepts either a single SQL entity -(a keyword or symbol) or a SQL clause. That's either -a column name or an `:on-constraint` clause or a -`:where` clause. +(a keyword or symbol), or a SQL clause, or a pair +of a SQL entity and a SQL clause. The SQL entity is +a column name and the SQL clause can be an +`:on-constraint` clause or a`:where` clause. `:on-constraint` accepts a single SQL entity that identifies a constraint name. @@ -629,9 +643,11 @@ will be ignored so `:do-nothing true` is a reasonable choices. `:do-update-set` accepts either a single SQL entity -(a keyword or symbol) or hash map of columns and -values, like `:set` (above). The former produces -a `SET` clause using `EXCLUDED`: +(a keyword or symbol), or hash map of columns and +values, like `:set` (above), or a hash map of fields +(a sequence of SQL entities) and a where clause. +The single SQL entity and the list of fields produce +`SET` clauses using `EXCLUDED`: ```clojure user=> (sql/format {:insert-into :companies @@ -639,6 +655,17 @@ user=> (sql/format {:insert-into :companies :on-conflict :name :do-update-set :name}) ["INSERT INTO companies (name) VALUES (?) ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name" "Microsoft"] +user=> (sql/format {:insert-into :companies + :values [{:name "Microsoft"}] + :on-conflict :name + :do-update-set {:name [:|| "was: " :EXCLUDED.name]}}) +["INSERT INTO companies (name) VALUES (?) ON CONFLICT (name) DO UPDATE SET name = ? || EXCLUDED.name" "Microsoft" "was: "] +user=> (sql/format {:insert-into :companies + :values [{:name "Microsoft"}] + :on-conflict :name + :do-update-set {:fields [:name] + :where [:<> :name nil]}}) +["INSERT INTO companies (name) VALUES (?) ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name WHERE name IS NOT NULL" "Microsoft"] user=> (sql/format {:insert-into :companies :values [{:name "Microsoft"}] :on-conflict {:on-constraint :name-idx} diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 719f9aa..8cf908a 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -493,13 +493,7 @@ :else (throw (ex-info "unsupported :on-conflict format" {:clause x})))) -(comment - keyword/symbol -> e = excluded.e - [k/s] -> join , e = excluded.e - {e v} -> join , e = v - {:fields f :where w} -> join , e = excluded.e (from f) where w - ,) (defn- format-do-update-set [k x] (if (map? x) (if (and (or (contains? x :fields) (contains? x 'fields)) From 267eef778a197eb92c174002cc7986d658aa259f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 17:30:16 -0800 Subject: [PATCH 138/254] Some more documentation! --- doc/differences-from-1-x.md | 9 +++++-- doc/getting-started.md | 49 ++++++++++++++++++++++++++++++++++--- 2 files changed, 53 insertions(+), 5 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 91f8728..591a94e 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -83,7 +83,7 @@ The `:quoting ` option has superseded by the new dialect machinery and Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. The following options are no longer supported: -* `:allow-dashed-names?` -- if you provide dashed-names in v2, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without); v1 treated names specified as keywords and names specified as strings differently. +* `:allow-dashed-names?` -- if you provide dashed-names in v2, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). * `:allow-namespaced-names?` -- this supported `foo/bar` column names in SQL which I'd like to discourage. * `:namespace-as-table?` -- this is the default in v2: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. * `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). @@ -102,7 +102,7 @@ The following new syntax has been added: * `:case` -- this is now explicit syntax, * `:cast` -- `[:cast expr :type]` => `CAST( expr AS type )`, * `:composite` -- explicit syntax to produce a comma-separated list of expressions, wrapped in parentheses, -* `:default` -- for `DEFAULT` values (in inserts), +* `:default` -- for `DEFAULT` values (in inserts) and for declaring column defaults in table definitions, * `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, * `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. * `:lift` -- used as a function to prevent interpretation of a Clojure data structure as DSL syntax (e.g., when passing a vector or hash map as a parameter value), @@ -113,6 +113,11 @@ The following new syntax has been added: > Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). +Several additional pieces of syntax have also been added to support column +definitions in `CREATE TABLE` clauses, now that v2 supports DDL statement +construction: `:constraint`, `:foreign-key`, `:index`, `:primary-key`, +`:references`, `:unique`, and -- as noted above -- `:default`. + You can now `SELECT` a function call more easily, using `[[...]]`. This was previously an error -- missing an alias -- but it was a commonly requested change, to avoid using `(sql/call ...)`: ```clojure diff --git a/doc/getting-started.md b/doc/getting-started.md index e8b986e..0233b8e 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -52,12 +52,14 @@ or symbols, are treated as positional parameters and replaced by `?` in the SQL string and lifted out into the vector that is returned from `format`. -Nearly all clauses expect a vector as their value, containing +Most clauses expect a vector as their value, containing either a list of SQL entities or the representation of a SQL -expression. +expression. Some clauses accept a single SQL entity. A few +accept a most specialized form (such as `:set` accepting a +hash map of SQL entities and SQL expressions). A SQL entity can be a simple keyword (or symbol) or a pair -that represents a SQL entity and its alias: +that represents a SQL entity and its alias (where aliases are allowed): ```clojure (sql/format {:select [:t.id [:name :item]], :from [[:table :t]], :where [:= :id 1]}) @@ -76,6 +78,8 @@ avoid evaluation: ```clojure (sql/format '{select [t.id [name item]], from [[table t]], where [= id 1]}) +;; or you can use (..) instead of [..] when quoted: +(sql/format '{select (t.id (name item)), from ((table t)), where (= id 1)}) ;; also produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` @@ -110,6 +114,12 @@ generally variadic and threadable: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` +There is a helper function for every single clause that HoneySQL +supports out of the box. In addition, there are helpers for +`composite` and `over` that make it easier to construct those +parts of the SQL DSL (examples of the former appear in the [README.md](README), +examples of the latter appear in the [docs/clause-reference.md](Clause Reference)) + In addition to being variadic -- which often lets you omit one level of `[`..`]` -- the helper functions merge clauses, which can make it easier to build queries programmatically: @@ -123,3 +133,36 @@ can make it easier to build queries programmatically: ;; produces: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` + +If you want to replace a clause with a subsequent helper call, +you need to explicitly remove the prior value: + +```clojure +(-> (select :t/id) + (from [:table :t]) + (where [:= :id 1]) + (dissoc :select) + (select [:name :item]) + (sql/format)) +;; produces: +;;=> ["SELECT name AS item FROM table AS t WHERE id = ?" 1] +``` + +Helpers always use keywords when constructing clauses so you +can rely on using keywords in `dissoc`. + +The following helpers shadow functions in `clojure.core` so +you need to consider this when referring symbols in from the +`honey.sql.helpers` namespace: `for`, `group-by`, `partition-by`, +`set`, and `update`. + +## Reference Documentation + +The full list of supported SQL clauses is documented in the +[docs/clause-reference.md](Clause Reference). The full list +of "special syntax" functions is documented in the +[docs/special-syntax.md](Special Syntax) section. The best +documentation for the helper functions is the +[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers). +If you're migrating to HoneySQL 2.0, this [overview of differences +between 1.0 and 2.0](docs/differences-from-1-x.md) should help. From e585ded37e38099b04d1f05f72a4b30095c2491e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 19:08:40 -0800 Subject: [PATCH 139/254] Restore upsert helper for #293 --- README.md | 8 ------- doc/clause-reference.md | 5 +++++ src/honey/sql.cljc | 37 ++++++++++++++++++------------- src/honey/sql/helpers.cljc | 19 +++++++++++++--- test/honey/sql/postgres_test.cljc | 28 ++++++++++++++++++----- 5 files changed, 65 insertions(+), 32 deletions(-) diff --git a/README.md b/README.md index 0541838..5018c6b 100644 --- a/README.md +++ b/README.md @@ -645,14 +645,6 @@ You can also register SQL clauses, specifying the keyword, the formatting functi If you find yourself registering an operator, a function (syntax), or a new clause, consider submitting a [pull request to HoneySQL](https://github.com/seancorfield/honeysql/pulls) so others can use it, too. If it is dialect-specific, let me know in the pull request. -## TODO - -- [ ] Create table, etc. - -## Extensions - -* [For PostgreSQL-specific extensions falling outside of ANSI SQL](https://github.com/nilenso/honeysql-postgres) -- these will all be core in 2.0! - ## License Copyright (c) 2020-2021 Sean Corfield. HoneySQL 1.x was copyright (c) 2012-2020 Justin Kramer and Sean Corfield. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index c53099f..29bad85 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -646,6 +646,11 @@ reasonable choices. (a keyword or symbol), or hash map of columns and values, like `:set` (above), or a hash map of fields (a sequence of SQL entities) and a where clause. +For convenience of building clauses with helpers, +it also accepts a sequence of one or more column +names followed by an optional hash map: this is treated +as an alternative form of the hash map with fields +and a where clause. The single SQL entity and the list of fields produce `SET` clauses using `EXCLUDED`: diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 8cf908a..2db8929 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -495,22 +495,27 @@ {:clause x})))) (defn- format-do-update-set [k x] - (if (map? x) - (if (and (or (contains? x :fields) (contains? x 'fields)) - (or (contains? x :where) (contains? x 'where))) - (let [sets (str/join ", " - (map (fn [e] - (let [e (format-entity e {:drop-ns true})] - (str e " = EXCLUDED." e))) - (or (:fields x) - ('fields x)))) - [sql & params] (format-dsl {:where - (or (:where x) - ('where x))})] - (into [(str (sql-kw k) " " sets " " sql)] params)) - (format-set-exprs k x)) - (let [e (format-entity x {:drop-ns true})] - [(str (sql-kw k) " " e " = EXCLUDED." e)]))) + (cond (map? x) + (if (or (contains? x :fields) (contains? x 'fields)) + (let [sets (str/join ", " + (map (fn [e] + (let [e (format-entity e {:drop-ns true})] + (str e " = EXCLUDED." e))) + (or (:fields x) + ('fields x)))) + where (or (:where x) ('where x)) + [sql & params] (when where (format-dsl {:where where}))] + (into [(str (sql-kw k) " " sets + (when sql (str " " sql)))] params)) + (format-set-exprs k x)) + (sequential? x) + (let [[cols clauses] (split-with (complement map?) x)] + (if (seq cols) + (recur k {:fields cols :where (:where (first clauses))}) + (recur k (first clauses)))) + :else + (let [e (format-entity x {:drop-ns true})] + [(str (sql-kw k) " " e " = EXCLUDED." e)]))) (defn- format-simple-clause [c] (binding [*inline* true] diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index a852f39..c09177d 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -106,7 +106,7 @@ (defn on-conflict [& args] (generic-1 :on-conflict args)) (defn on-constraint [& args] (generic :on-constraint args)) (defn do-nothing [& args] (generic :do-nothing args)) -(defn do-update-set [& args] (generic-1 :do-update-set args)) +(defn do-update-set [& args] (generic :do-update-set args)) (defn returning [& args] (generic :returning args)) ;; helpers that produce non-clause expressions -- must be listed below: @@ -114,8 +114,21 @@ ;; to make this easy to use in a select, wrap it so it becomes a function: (defn over [& args] [(into [:over] args)]) -;; helper to ease compatibility with former nilenso/honeysql-postgres code: -(defn upsert [data & clauses] (default-merge data clauses)) +;; this helper is intended to ease the migration from nilenso: +(defn upsert + ([clause] (upsert {} clause)) + ([data clause] + (let [{:keys [on-conflict do-nothing do-update-set where]} clause] + (cond-> data + on-conflict + (assoc :on-conflict on-conflict) + do-nothing + (assoc :do-nothing do-nothing) + do-update-set + (assoc :do-update-set (if where + {:fields do-update-set + :where where} + do-update-set)))))) #?(:clj (assert (= (clojure.core/set (conj @@#'h/base-clause-order diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 98a745e..2812fbc 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -14,9 +14,7 @@ ;; pull in all the PostgreSQL helpers that the nilenso ;; library provided (as well as the regular HoneySQL ones): [honey.sql.helpers :as sqlh :refer - [;; not needed because on-conflict accepts clauses - #_upsert - on-conflict do-nothing on-constraint + [upsert on-conflict do-nothing on-constraint returning do-update-set ;; not needed because do-update-set can do this directly #_do-update-set! @@ -44,18 +42,38 @@ (do-update-set :dname) (returning :*) sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + (-> (insert-into :distributors) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (upsert (-> (on-conflict :did) + (do-update-set :dname))) + (returning :*) + sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (on-conflict :did) do-nothing sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] + (-> (insert-into :distributors) + (values [{:did 7 :dname "Redline GmbH"}]) + (upsert (-> (on-conflict :did) + do-nothing)) + sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) (on-conflict (on-constraint :distributors_pkey)) do-nothing sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + (upsert (-> (on-conflict (on-constraint :distributors_pkey)) + do-nothing)) + sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname" 10 "Pinp Design" 11 "Foo Bar Works"] (sql/format {:insert-into :distributors :values [{:did 10 :dname "Pinp Design"} @@ -73,8 +91,8 @@ (-> (insert-into [:distributors [:did :dname]] (select 1 "whatever")) #_(query-values (select 1 "whatever")) - (on-conflict (on-constraint :distributors_pkey)) - do-nothing + (upsert (-> (on-conflict (on-constraint :distributors_pkey)) + do-nothing)) sql/format))))) (deftest upsert-where-test From 2d9ceb73a60864f7691583d619956face67a5220 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 21:10:49 -0800 Subject: [PATCH 140/254] Expand documentation --- doc/getting-started.md | 131 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 131 insertions(+) diff --git a/doc/getting-started.md b/doc/getting-started.md index 0233b8e..98307a7 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -96,6 +96,69 @@ the table name, i.e., `:foo/bar` instead of `:foo.bar`: ;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1] ``` +## SQL Expressions + +In addition to using hash maps to describe SQL clauses, +HoneySQL uses vectors to describe SQL expressions. Any +sequence that begins with a keyword (or symbol) is considered +to be a kind of function invocation. Certain "functions" are +considered to be "special syntax" and have custom rendering. +Some "functions" are considered to be operators. In general, +`[:foo :a 42 "c"]` will render as `FOO(a, ?, ?)` with the parameters +`42` and `"c"` lifted out into the overall vector result +(with a SQL string followed by all its parameters). + +Operators can be strictly binary or variadic (most are strictly binary). +Special syntax can have zero or more arguments and each form is +described in the [docs/special-syntax.md](Special Syntax) section. + +Some examples: + +```clojure +[:= :a 42] ;=> "a = ?" with a parameter of 42 +[:+ 42 :a :b] ;=> "? + a + b" with a parameter of 42 +[:= :x [:inline "foo"]] ;=> "x = 'foo'" -- the string is inlined +[:now] ;=> "NOW()" +[:count :*] ;=> "COUNT(*)" +[:or [:<> :name nil] [:= :status-id 0]] ;=> "(name IS NOT NULL) OR (status_id = ?)" +;; with a parameter of 0 -- the nil value is inlined as NULL +``` + +`:inline` is an example of "special syntax" and it renders its +(single) argument as part of the SQL string generated by `format`. + +## SQL Parameters + +As indicated in the preceding sections, values found in the DSL data structure +that are not keywords or symbols are lifted out as positional parameters. +They are replaced by `?` in the generated SQL string and added to the +parameter list in order: + +```clojure +[:between :size 10 20] ;=> "size BETWEEN ? AND ?" with parameters 10 and 20 +``` + +HoneySQL also supports named parameters. There are two ways +of identifying a named parameter: +* a keyword or symbol that begins with `?` +* the `:param` special (functional) syntax + +The values of those parameters are supplied in the `format` +call as the `:params` key of the options hash map. + +```clojure +(sql/format {:select [:*] :from [:table] + :where [:= :a :?x]} + {:params {:x 42}}) +["SELECT * FROM table WHERE a = ?" 42] +(sql/format {:select [:*] :from [:table] + :where [:= :a [:param :x]]} + {:params {:x 42}}) +["SELECT * FROM table WHERE a = ?" 42] +``` + +## Functional Helpers + In addition to the hash map (and vectors) approach of building SQL queries with raw Clojure data structures, a namespace full of helper functions is also available. These functions are @@ -156,10 +219,78 @@ you need to consider this when referring symbols in from the `honey.sql.helpers` namespace: `for`, `group-by`, `partition-by`, `set`, and `update`. +## Dialects + +By default, HoneySQL operates in ANSI SQL mode but it supports +a lot of PostgreSQL extensions in that mode. PostgreSQL is mostly +a superset of ANSI SQL so it makes sense to support as much as +possible of the union of ANSI SQL and PostgreSQL out of the box. + +The dialects supported by HoneySQL v2 are: +* `:ansi` -- the default, including most PostgreSQL extensions +* `:sqlserver` -- Microsoft SQL Server +* `:mysql` -- MySQL (and Percona and MariaDB) +* `:oracle` -- Oracle + +The most visible difference between dialects is how SQL entities +should be quoted (if the `:quoted true` option is provided to `format`). +Most databases use `"` for quoting (the `:ansi` and `:oracle` dialects). +The `:sqlserver` dialect uses `[`..`]` and the `:mysql` dialect uses +```..```. + +Currently, the only dialect that has substantive differences from +the others is `:mysql` which has a `:lock` clause (that is very +similar to the ANSI `:for` clause) and for which the `:set` clause +has a different precedence than ANSI SQL. + +You can change the dialect globally using the `set-dialect!` function, +passing in one of the keywords above. You need to call this function +before you call `format` for the first time. + +You can change the dialect for a single `format` call by +specifying the `:dialect` option in that call. + +SQL entities are not quoted by default but if you specify the +dialect in a `format` call, they will be quoted. If you don't +specify a dialect in the `format` call, you can specify +`:quoted true` to have SQL entities quoted. + +```clojure +(sql/format '{select (id) from (table)} {:quoted true}) +;;=> ["SELECT \"id\" FROM \"table\""] +(sql/format '{select (id) from (table)} {:dialect :mysql}) +;;=> ["SELECT `id` FROM `table`"] +(sql/set-dialect! :sqlserver) +;;=> nil +(sql/format '{select (id) from (table)} {:quoted true}) +;;=> ["SELECT [id] FROM [table]"] +``` + +## Format Options + +In addition to the `:quoted` and `:dialect` options described above, +`format` also accepts `:inline` and `:params`. + +The `:params` option was mentioned above and is used to specify +the values of named parameters in the DSL. + +The `:inline` option suppresses the generation of parameters in +the SQL string and instead tries to inline all the values directly +into the SQL string. The behavior is as if each value in the DSL +was wrapped in `[:inline `..`]`: + +* `nil` becomes the SQL value `NULL`, +* Clojure strings become inline SQL strings with single quotes (so `"foo"` becomes `'foo'`), +* keywords and symbols become SQL keywords (uppercase, with `-` replaced by a space), +* everything else is just turned into a string (by calling `str`) and added to the SQL string. + ## Reference Documentation The full list of supported SQL clauses is documented in the [docs/clause-reference.md](Clause Reference). The full list +of operators supported (as prefix-form "functions") is +documented in the [docs/operator-reference.md](Operator Reference) +section. The full list of "special syntax" functions is documented in the [docs/special-syntax.md](Special Syntax) section. The best documentation for the helper functions is the From 645ce897c54c2cf7c56b70bebba3bd0455407da0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 21:17:25 -0800 Subject: [PATCH 141/254] Document % function shorthand --- doc/getting-started.md | 11 +++++++++++ 1 file changed, 11 insertions(+) diff --git a/doc/getting-started.md b/doc/getting-started.md index 98307a7..a4f155d 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -127,6 +127,17 @@ Some examples: `:inline` is an example of "special syntax" and it renders its (single) argument as part of the SQL string generated by `format`. +Another form of special syntax that is treated as function calls +is keywords or symbols that begin with `%`. Such keywords (or symbols) +are split at `.` and turned into function calls: + +```clojure +%now ;=> NOW() +%count.* ;=> COUNT(*) +%max.foo ;=> MAX(foo) +%f.a.b ;=> F(a,b) +``` + ## SQL Parameters As indicated in the preceding sections, values found in the DSL data structure From 38da6f567b79a096a9ee4b3a994a1779936d96af Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 21:29:22 -0800 Subject: [PATCH 142/254] Fixes #294 by applying inline everywhere --- src/honey/sql.cljc | 47 ++++++++++++++++++++++++++++------------------ 1 file changed, 29 insertions(+), 18 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 2db8929..2c1db38 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -145,6 +145,14 @@ (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) +(defn- sqlize-value [x] + (cond + (nil? x) "NULL" + (string? x) (str \' (str/replace x "'" "''") \') + (symbol? x) (sql-kw x) + (keyword? x) (sql-kw x) + :else (str x))) + (defn format-entity "Given a simple SQL entity (a keyword or symbol -- or string), return the equivalent SQL fragment (as a string -- no parameters). @@ -166,15 +174,16 @@ t (str (q t) ".")))) +(defn- param-value [k] + (if (contains? *params* k) + (get *params* k) + (throw (ex-info (str "missing parameter value for " k) + {:params (keys *params*)})))) + (defn- ->param [k] (with-meta (constantly k) {::wrapper - (fn [fk _] - (let [k (fk)] - (if (contains? *params* k) - (get *params* k) - (throw (ex-info (str "missing parameter value for " k) - {:params (keys *params*)})))))})) + (fn [fk _] (param-value (fk)))})) (defn- format-var [x & [opts]] (let [c (name-_ x)] @@ -183,7 +192,10 @@ ;; TODO: this does not quote arguments -- does that matter? [(str (upper-case f) "(" (str/join "," args) ")")]) (= \? (first c)) - ["?" (->param (keyword (subs c 1)))] + (let [k (keyword (subs c 1))] + (if *inline* + [(sqlize-value (param-value k))] + ["?" (->param k)])) :else [(format-entity x opts)]))) @@ -701,14 +713,6 @@ (def ^:private op-ignore-nil (atom #{:and :or})) (def ^:private op-variadic (atom #{:and :or :+ :* :||})) -(defn- sqlize-value [x] - (cond - (nil? x) "NULL" - (string? x) (str \' (str/replace x "'" "''") \') - (symbol? x) (sql-kw x) - (keyword? x) (sql-kw x) - :else (str x))) - (defn- unwrap [x opts] (if-let [m (meta x)] (if-let [f (::wrapper m)] @@ -821,8 +825,13 @@ (into [(str "INTERVAL " sql " " (sql-kw units))] params))) :lift (fn [_ [x]] - ["?" (with-meta (constantly x) - {::wrapper (fn [fx _] (fx))})]) + (if *inline* + ;; this is pretty much always going to be wrong, + ;; but it could produce a valid result so we just + ;; assume that the user knows what they are doing: + [(sqlize-value x)] + ["?" (with-meta (constantly x) + {::wrapper (fn [fx _] (fx))})])) :nest (fn [_ [x]] (format-expr x {:nested true})) @@ -846,7 +855,9 @@ (into [(str/join ", " sqls)] params))) :param (fn [_ [k]] - ["?" (->param k)]) + (if *inline* + [(sqlize-value (param-value k))] + ["?" (->param k)])) :raw (fn [_ [s]] (if (sequential? s) From 22384b9daa7053c8a30ad93a74202be3205bf134 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 21:40:32 -0800 Subject: [PATCH 143/254] Fix links --- doc/clause-reference.md | 2 +- doc/cljdoc.edn | 1 + doc/getting-started.md | 15 +++++++++------ doc/postgresql.md | 4 ++++ 4 files changed, 15 insertions(+), 7 deletions(-) create mode 100644 doc/postgresql.md diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 29bad85..8b3cc38 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -114,7 +114,7 @@ the column name from the SQL keywords). Various function-like expressions can be specified, as shown in the example above, but allow things like `CHECK` for a constraint, `FOREIGN KEY` (with a column name), `REFERENCES` -(with a pair of column names). See [special-syntax.md#clause-descriptors](Clause Descriptors in Special Syntax) for more details. +(with a pair of column names). See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. ## create-view diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn index 0326f74..643c7a6 100644 --- a/doc/cljdoc.edn +++ b/doc/cljdoc.edn @@ -5,5 +5,6 @@ ["SQL Clause Reference" {:file "doc/clause-reference.md"}] ["SQL Operator Reference" {:file "doc/operator-reference.md"}] ["SQL 'Special Syntax'" {:file "doc/special-syntax.md"}] + ["PostgreSQL Support" {:file "doc/postgresql.md"}] ["Extending HoneySQL" {:file "doc/extending-honeysql.md"}]] ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} diff --git a/doc/getting-started.md b/doc/getting-started.md index a4f155d..8655f02 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -110,7 +110,7 @@ Some "functions" are considered to be operators. In general, Operators can be strictly binary or variadic (most are strictly binary). Special syntax can have zero or more arguments and each form is -described in the [docs/special-syntax.md](Special Syntax) section. +described in the [Special Syntax](docs/special-syntax.md) section. Some examples: @@ -191,8 +191,8 @@ generally variadic and threadable: There is a helper function for every single clause that HoneySQL supports out of the box. In addition, there are helpers for `composite` and `over` that make it easier to construct those -parts of the SQL DSL (examples of the former appear in the [README.md](README), -examples of the latter appear in the [docs/clause-reference.md](Clause Reference)) +parts of the SQL DSL (examples of the former appear in the [README](README.md), +examples of the latter appear in the [Clause Reference](docs/clause-reference.md)) In addition to being variadic -- which often lets you omit one level of `[`..`]` -- the helper functions merge clauses, which @@ -277,6 +277,9 @@ specify a dialect in the `format` call, you can specify ;;=> ["SELECT [id] FROM [table]"] ``` +Out of the box, as part of the extended ANSI SQL support, +HoneySQL supports quite a few [PostgreSQL extensions](docs/postgresql.md) + ## Format Options In addition to the `:quoted` and `:dialect` options described above, @@ -300,11 +303,11 @@ was wrapped in `[:inline `..`]`: The full list of supported SQL clauses is documented in the [docs/clause-reference.md](Clause Reference). The full list of operators supported (as prefix-form "functions") is -documented in the [docs/operator-reference.md](Operator Reference) +documented in the [Operator Reference](docs/operator-reference.md) section. The full list of "special syntax" functions is documented in the -[docs/special-syntax.md](Special Syntax) section. The best +[Special Syntax](docs/special-syntax.md) section. The best documentation for the helper functions is the -[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers). +[https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers](honey.sql.helpers). If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](docs/differences-from-1-x.md) should help. diff --git a/doc/postgresql.md b/doc/postgresql.md new file mode 100644 index 0000000..e509f07 --- /dev/null +++ b/doc/postgresql.md @@ -0,0 +1,4 @@ +# PostgreSQL Support + +This section will document the PostgreSQL-specific +features that HoneySQL supports out of the box. From e23502eba8f5819807871de70dd4b37323601eaa Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 22:06:43 -0800 Subject: [PATCH 144/254] Add create/drop extension #293 --- src/honey/sql.cljc | 3 +++ src/honey/sql/helpers.cljc | 2 ++ test/honey/sql/postgres_test.cljc | 34 ++++++++++++++----------------- 3 files changed, 20 insertions(+), 19 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 2c1db38..3c86e63 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -40,6 +40,7 @@ :alter-table :add-column :drop-column :modify-column :rename-column :add-index :drop-index :rename-table :create-table :with-columns :create-view :drop-table + :create-extension :drop-extension ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :select-distinct-on @@ -609,9 +610,11 @@ :drop-index #'format-selector :rename-table (fn [_ x] (format-selector :rename-to x)) :create-table #'format-create-table + :create-extension #'format-create-table :with-columns #'format-table-columns :create-view #'format-create-view :drop-table #'format-drop-table + :drop-extension #'format-drop-table :nest (fn [_ x] (format-expr x)) :with #'format-with :with-recursive #'format-with diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index c09177d..ada71c8 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -52,6 +52,7 @@ (defn drop-index [& args] (generic-1 :drop-index args)) (defn rename-table [& args] (generic-1 :rename-table args)) (defn create-table [& args] (generic :create-table args)) +(defn create-extension [& args] (generic :create-extension args)) (defn with-columns [& args] ;; special case so (with-columns [[:col-1 :definition] [:col-2 :definition]]) ;; also works in addition to (with-columns [:col-1 :definition] [:col-2 :definition]) @@ -63,6 +64,7 @@ (generic :with-columns args))) (defn create-view [& args] (generic-1 :create-view args)) (defn drop-table [& args] (generic :drop-table args)) +(defn drop-extension [& args] (generic :drop-extension args)) (defn nest [& args] (generic :nest args)) (defn with [& args] (generic :with args)) (defn with-recursive [& args] (generic :with-recursive args)) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 2812fbc..3c2058b 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -24,8 +24,7 @@ #_insert-into-as create-table rename-table drop-table window create-view over with-columns - ;; temporarily disable until these are also implemented: - #_#_create-extension drop-extension + create-extension drop-extension select-distinct-on ;; already part of HoneySQL insert-into values where select @@ -314,21 +313,18 @@ (modifiers :distinct-on :a :b) (sql/format :quoting :ansi)))))) -#_(deftest create-extension-test - (testing "create extension" - (is (= ["CREATE EXTENSION \"uuid-ossp\""] - (-> (create-extension :uuid-ossp) - (sql/format :allow-dashed-names? true - :quoting :ansi))))) - (testing "create extension if not exists" - (is (= ["CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\""] - (-> (create-extension :uuid-ossp :if-not-exists? true) - (sql/format :allow-dashed-names? true - :quoting :ansi)))))) +(deftest create-extension-test + (testing "create extension" + (is (= ["CREATE EXTENSION \"uuid-ossp\""] + (-> (create-extension :uuid-ossp) + (sql/format {:quoted true}))))) + (testing "create extension if not exists" + (is (= ["CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\""] + (-> (create-extension :uuid-ossp :if-not-exists? true) + (sql/format {:quoted true})))))) -#_(deftest drop-extension-test - (testing "create extension" - (is (= ["DROP EXTENSION \"uuid-ossp\""] - (-> (drop-extension :uuid-ossp) - (sql/format :allow-dashed-names? true - :quoting :ansi)))))) +(deftest drop-extension-test + (testing "create extension" + (is (= ["DROP EXTENSION \"uuid-ossp\""] + (-> (drop-extension :uuid-ossp) + (sql/format {:quoted true})))))) From fea5c742603921f91d4a0c0f07da8b85c3e35aaa Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 22:10:10 -0800 Subject: [PATCH 145/254] Set up for 2.0 Alpha 1 --- doc/getting-started.md | 2 -- 1 file changed, 2 deletions(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 8655f02..3542cb9 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -18,8 +18,6 @@ For Leiningen, add the following dependency to your `project.clj` file: [seancorfield/honeysql "2.0.0-alpha1"] ``` -> Note: 2.0.0-alpha1 will be released shortly! - HoneySQL produces SQL statements but does not execute them. To execute SQL statements, you will also need a JDBC wrapper like [`seancorfield/next.jdbc`](https://github.com/seancorfield/next-jdbc) and a JDBC driver for the database you use. From 41b1ce0eb86d8475fb984309be08a4451c97a690 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Feb 2021 22:20:18 -0800 Subject: [PATCH 146/254] Fix some links --- doc/getting-started.md | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 3542cb9..b793177 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -108,7 +108,7 @@ Some "functions" are considered to be operators. In general, Operators can be strictly binary or variadic (most are strictly binary). Special syntax can have zero or more arguments and each form is -described in the [Special Syntax](docs/special-syntax.md) section. +described in the [Special Syntax](special-syntax.md) section. Some examples: @@ -276,7 +276,7 @@ specify a dialect in the `format` call, you can specify ``` Out of the box, as part of the extended ANSI SQL support, -HoneySQL supports quite a few [PostgreSQL extensions](docs/postgresql.md) +HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md) ## Format Options @@ -299,13 +299,13 @@ was wrapped in `[:inline `..`]`: ## Reference Documentation The full list of supported SQL clauses is documented in the -[docs/clause-reference.md](Clause Reference). The full list +[Clause Reference](clause-reference.md). The full list of operators supported (as prefix-form "functions") is -documented in the [Operator Reference](docs/operator-reference.md) +documented in the [Operator Reference](operator-reference.md) section. The full list of "special syntax" functions is documented in the -[Special Syntax](docs/special-syntax.md) section. The best +[Special Syntax](special-syntax.md) section. The best documentation for the helper functions is the [https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers](honey.sql.helpers). If you're migrating to HoneySQL 2.0, this [overview of differences -between 1.0 and 2.0](docs/differences-from-1-x.md) should help. +between 1.0 and 2.0](differences-from-1-x.md) should help. From 0029402ae78490d9ca9497824d19223bff042d4c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 10:36:37 -0800 Subject: [PATCH 147/254] Fix typo in cljdoc.edn --- doc/cljdoc.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn index 643c7a6..024ed98 100644 --- a/doc/cljdoc.edn +++ b/doc/cljdoc.edn @@ -7,4 +7,4 @@ ["SQL 'Special Syntax'" {:file "doc/special-syntax.md"}] ["PostgreSQL Support" {:file "doc/postgresql.md"}] ["Extending HoneySQL" {:file "doc/extending-honeysql.md"}]] - ["Differences from 1.x" {:file "doc/difference-from-1-x.md"}]]} + ["Differences from 1.x" {:file "doc/differences-from-1-x.md"}]]} From 66d9f9dacbebf933de1736f2fec94ef6b1df3a0c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 10:45:49 -0800 Subject: [PATCH 148/254] Fix some version-related links --- README.md | 2 +- doc/getting-started.md | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index 5018c6b..e4d0c27 100644 --- a/README.md +++ b/README.md @@ -12,7 +12,7 @@ This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINO Prerelease builds of the upcoming 2.x version of HoneySQL will soon be available: -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/CURRENT) +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/v2.0.0-alpha1) This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). diff --git a/doc/getting-started.md b/doc/getting-started.md index b793177..1cb49d2 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -306,6 +306,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is the -[https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers](honey.sql.helpers). +[https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/api/honey.sql.helpers](honey.sql.helpers). If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. From efa2fe6af55f6c657ad3e3f2657a3335b9619c59 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 10:59:41 -0800 Subject: [PATCH 149/254] Fix v2 badge --- README.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index e4d0c27..9f1ceb1 100644 --- a/README.md +++ b/README.md @@ -12,11 +12,11 @@ This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINO Prerelease builds of the upcoming 2.x version of HoneySQL will soon be available: -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/v2.0.0-alpha1) +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1) This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). -See this [summary of differences between v1 and v2](https://github.com/seancorfield/honeysql/blob/v2/doc/differences-from-1-x.md) if you want to help test v2! +See this [summary of differences between v1 and v2](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/doc/differences-from-1-x) if you want to help test v2! ## Note on code samples From 78fe59d98cebdd417304a7beda2817d7159dfd6e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 11:04:39 -0800 Subject: [PATCH 150/254] Fix one more link! --- doc/getting-started.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 1cb49d2..09d3865 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -305,7 +305,7 @@ documented in the [Operator Reference](operator-reference.md) section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best -documentation for the helper functions is the -[https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/api/honey.sql.helpers](honey.sql.helpers). +documentation for the helper functions is in the +[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. From f84726a48b9d3f5d333dc560d85f515aa77b42b3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 11:37:27 -0800 Subject: [PATCH 151/254] Reformatting to prepare for docstring addition --- src/honey/sql/helpers.cljc | 294 +++++++++++++++++++++++++++++-------- 1 file changed, 234 insertions(+), 60 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index ada71c8..2620056 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -3,7 +3,9 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." (:refer-clojure :exclude [update set group-by for partition-by]) - (:require [honey.sql :as h])) + (:require [honey.sql])) + +;; implementation helpers: (defn- default-merge [current args] (into (vec current) args)) @@ -43,17 +45,50 @@ (assoc data k arg) (assoc {} k data))) -(defn alter-table [& args] (generic :alter-table args)) -(defn add-column [& args] (generic :add-column args)) -(defn drop-column [& args] (generic-1 :drop-column args)) -(defn modify-column [& args] (generic :modify-column args)) -(defn rename-column [& args] (generic :rename-column args)) -(defn add-index [& args] (generic :add-index args)) -(defn drop-index [& args] (generic-1 :drop-index args)) -(defn rename-table [& args] (generic-1 :rename-table args)) -(defn create-table [& args] (generic :create-table args)) -(defn create-extension [& args] (generic :create-extension args)) -(defn with-columns [& args] +;; for every clause, there is a public helper + +(defn alter-table + [& args] + (generic :alter-table args)) + +(defn add-column + [& args] + (generic :add-column args)) + +(defn drop-column + [& args] + (generic-1 :drop-column args)) + +(defn modify-column + [& args] + (generic :modify-column args)) + +(defn rename-column + [& args] + (generic :rename-column args)) + +(defn add-index + [& args] + (generic :add-index args)) + +(defn drop-index + [& args] + (generic-1 :drop-index args)) + +(defn rename-table + [& args] + (generic-1 :rename-table args)) + +(defn create-table + [& args] + (generic :create-table args)) + +(defn create-extension + [& args] + (generic :create-extension args)) + +(defn with-columns + [& args] ;; special case so (with-columns [[:col-1 :definition] [:col-2 :definition]]) ;; also works in addition to (with-columns [:col-1 :definition] [:col-2 :definition]) (cond (and (= 1 (count args)) (sequential? (first args)) (sequential? (ffirst args))) @@ -62,59 +97,198 @@ (generic-1 :with-columns args) :else (generic :with-columns args))) -(defn create-view [& args] (generic-1 :create-view args)) -(defn drop-table [& args] (generic :drop-table args)) -(defn drop-extension [& args] (generic :drop-extension args)) -(defn nest [& args] (generic :nest args)) -(defn with [& args] (generic :with args)) -(defn with-recursive [& args] (generic :with-recursive args)) + +(defn create-view + [& args] + (generic-1 :create-view args)) + +(defn drop-table + [& args] + (generic :drop-table args)) + +(defn drop-extension + [& args] + (generic :drop-extension args)) + +(defn nest + [& args] + (generic :nest args)) + +(defn with + [& args] + (generic :with args)) + +(defn with-recursive + [& args] + (generic :with-recursive args)) + ;; these five need to supply an empty hash map since they wrap ;; all of their arguments: -(defn intersect [& args] (generic :intersect (cons {} args))) -(defn union [& args] (generic :union (cons {} args))) -(defn union-all [& args] (generic :union-all (cons {} args))) -(defn except [& args] (generic :except (cons {} args))) -(defn except-all [& args] (generic :except-all (cons {} args))) +(defn intersect + [& args] + (generic :intersect (cons {} args))) -(defn select [& args] (generic :select args)) -(defn select-distinct [& args] (generic :select-distinct args)) -(defn select-distinct-on [& args] (generic :select-distinct-on args)) -(defn insert-into [& args] (generic :insert-into args)) -(defn update [& args] (generic :update args)) -(defn delete [& args] (generic-1 :delete args)) -(defn delete-from [& args] (generic :delete-from args)) -(defn truncate [& args] (generic :truncate args)) -(defn columns [& args] (generic :columns args)) -(defn set [& args] (generic-1 :set args)) -(defn from [& args] (generic :from args)) -(defn using [& args] (generic :using args)) -(defn join [& args] (generic :join args)) -(defn left-join [& args] (generic :left-join args)) -(defn right-join [& args] (generic :right-join args)) -(defn inner-join [& args] (generic :inner-join args)) -(defn outer-join [& args] (generic :outer-join args)) -(defn full-join [& args] (generic :full-join args)) -(defn cross-join [& args] (generic :cross-join args)) -(defn where [& args] (generic :where args)) -(defn group-by [& args] (generic :group-by args)) -(defn having [& args] (generic :having args)) -(defn window [& args] (generic :window args)) -(defn partition-by [& args] (generic :partition-by args)) -(defn order-by [& args] (generic :order-by args)) -(defn limit [& args] (generic-1 :limit args)) -(defn offset [& args] (generic-1 :offset args)) -(defn for [& args] (generic-1 :for args)) -(defn values [& args] (generic-1 :values args)) -(defn on-conflict [& args] (generic-1 :on-conflict args)) -(defn on-constraint [& args] (generic :on-constraint args)) -(defn do-nothing [& args] (generic :do-nothing args)) -(defn do-update-set [& args] (generic :do-update-set args)) -(defn returning [& args] (generic :returning args)) +(defn union + [& args] + (generic :union (cons {} args))) + +(defn union-all + [& args] + (generic :union-all (cons {} args))) + +(defn except + [& args] + (generic :except (cons {} args))) + +(defn except-all + [& args] + (generic :except-all (cons {} args))) + +(defn select + [& args] + (generic :select args)) + +(defn select-distinct + [& args] + (generic :select-distinct args)) + +(defn select-distinct-on + [& args] + (generic :select-distinct-on args)) + +(defn insert-into + [& args] + (generic :insert-into args)) + +(defn update + [& args] + (generic :update args)) + +(defn delete + [& args] + (generic-1 :delete args)) + +(defn delete-from + [& args] + (generic :delete-from args)) + +(defn truncate + [& args] + (generic :truncate args)) + +(defn columns + [& args] + (generic :columns args)) + +(defn set + [& args] + (generic-1 :set args)) + +(defn from + [& args] + (generic :from args)) + +(defn using + [& args] + (generic :using args)) + +(defn join + [& args] + (generic :join args)) + +(defn left-join + [& args] + (generic :left-join args)) + +(defn right-join + [& args] + (generic :right-join args)) + +(defn inner-join + [& args] + (generic :inner-join args)) + +(defn outer-join + [& args] + (generic :outer-join args)) + +(defn full-join + [& args] + (generic :full-join args)) + +(defn cross-join + [& args] + (generic :cross-join args)) + +(defn where + [& args] + (generic :where args)) + +(defn group-by + [& args] + (generic :group-by args)) + +(defn having + [& args] + (generic :having args)) + +(defn window + [& args] + (generic :window args)) + +(defn partition-by + [& args] + (generic :partition-by args)) + +(defn order-by + [& args] + (generic :order-by args)) + +(defn limit + [& args] + (generic-1 :limit args)) + +(defn offset + [& args] + (generic-1 :offset args)) + +(defn for + [& args] + (generic-1 :for args)) + +(defn values + [& args] + (generic-1 :values args)) + +(defn on-conflict + [& args] + (generic-1 :on-conflict args)) + +(defn on-constraint + [& args] + (generic :on-constraint args)) + +(defn do-nothing + [& args] + (generic :do-nothing args)) + +(defn do-update-set + [& args] + (generic :do-update-set args)) + +(defn returning + [& args] + (generic :returning args)) ;; helpers that produce non-clause expressions -- must be listed below: -(defn composite [& args] (into [:composite] args)) +(defn composite + [& args] + (into [:composite] args)) + ;; to make this easy to use in a select, wrap it so it becomes a function: -(defn over [& args] [(into [:over] args)]) +(defn over + [& args] + [(into [:over] args)]) ;; this helper is intended to ease the migration from nilenso: (defn upsert @@ -133,6 +307,6 @@ do-update-set)))))) #?(:clj - (assert (= (clojure.core/set (conj @@#'h/base-clause-order + (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order :composite :over :upsert)) (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) From a7ee19ee2bd444b229d4052855b82604554be88b Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 12:50:24 -0800 Subject: [PATCH 152/254] Add cljdoc.edn check to CI --- .github/workflows/test.yml | 2 ++ 1 file changed, 2 insertions(+) diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index 44ec488..f80d1cb 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -20,3 +20,5 @@ jobs: tools-deps: '1.10.1.754' - name: Run Tests run: sh run-tests.sh all + - name: Check cljdoc.edn + run: curl -fsSL https://raw.githubusercontent.com/cljdoc/cljdoc/master/script/verify-cljdoc-edn | bash -s doc/cljdoc.edn From 5c8a8d0eb6ebe4ffa95116d63cee98e217aa0f4e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 13:05:40 -0800 Subject: [PATCH 153/254] Update CLI version for CI --- .circleci/config.yml | 2 +- .github/workflows/test.yml | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 234a5c4..f85d665 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -3,7 +3,7 @@ jobs: build: working_directory: ~/honeysql docker: - - image: circleci/clojure:openjdk-11-tools-deps-1.10.1.754 + - image: circleci/clojure:openjdk-11-tools-deps-1.10.1.774 steps: - checkout - restore_cache: diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index f80d1cb..379317d 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -17,7 +17,7 @@ jobs: - name: Setup Clojure uses: DeLaGuardo/setup-clojure@master with: - tools-deps: '1.10.1.754' + tools-deps: '1.10.1.774' - name: Run Tests run: sh run-tests.sh all - name: Check cljdoc.edn From 67c85ba57cd2b5f6b83189c1f55b60490ddc7134 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 13:07:11 -0800 Subject: [PATCH 154/254] Oops: 1.10.2.774 (not 1.10.1.774) --- .circleci/config.yml | 2 +- .github/workflows/test.yml | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index f85d665..6046d5c 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -3,7 +3,7 @@ jobs: build: working_directory: ~/honeysql docker: - - image: circleci/clojure:openjdk-11-tools-deps-1.10.1.774 + - image: circleci/clojure:openjdk-11-tools-deps-1.10.2.774 steps: - checkout - restore_cache: diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index 379317d..d29c6e3 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -17,7 +17,7 @@ jobs: - name: Setup Clojure uses: DeLaGuardo/setup-clojure@master with: - tools-deps: '1.10.1.774' + tools-deps: '1.10.2.774' - name: Run Tests run: sh run-tests.sh all - name: Check cljdoc.edn From 26741450e6f5d8f19820e9a03e2c85d09d683aa9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 14:00:28 -0800 Subject: [PATCH 155/254] Note relation between :lift and honeysql.format/value --- doc/differences-from-1-x.md | 2 +- doc/special-syntax.md | 2 ++ 2 files changed, 3 insertions(+), 1 deletion(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 591a94e..6ba6831 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -105,7 +105,7 @@ The following new syntax has been added: * `:default` -- for `DEFAULT` values (in inserts) and for declaring column defaults in table definitions, * `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, * `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. -* `:lift` -- used as a function to prevent interpretation of a Clojure data structure as DSL syntax (e.g., when passing a vector or hash map as a parameter value), +* `:lift` -- used as a function to prevent interpretation of a Clojure data structure as DSL syntax (e.g., when passing a vector or hash map as a parameter value) -- this should mostly be a replacement for `honeysql.format/value`, * `:nest` -- used as a function to add an extra level of nesting (parentheses) around an expression, * `:not` -- this is now explicit syntax, * `:param` -- used as a function to replace the `sql/param` / `#sql/param` machinery, diff --git a/doc/special-syntax.md b/doc/special-syntax.md index f75a6cf..fe47013 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -98,6 +98,8 @@ This can be useful when dealing with JSON types: ;;=> ["WHERE json_col = ?" {:a 1 :b "two"}] ``` +> Note: HoneySQL 1.x used `honeysql.format/value` for this. + ## nest Used to wrap an expression when you want an extra From 2af7d0b6902b149c442f43d1ecf23473108fb585 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 14:17:31 -0800 Subject: [PATCH 156/254] Document :exists difference --- doc/differences-from-1-x.md | 20 ++++++++++++++++---- 1 file changed, 16 insertions(+), 4 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 6ba6831..b591f79 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -121,16 +121,28 @@ construction: `:constraint`, `:foreign-key`, `:index`, `:primary-key`, You can now `SELECT` a function call more easily, using `[[...]]`. This was previously an error -- missing an alias -- but it was a commonly requested change, to avoid using `(sql/call ...)`: ```clojure - (sql/format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) - ;; select a (column), b (aliased to c), d (fn call), f (fn call, aliased to h): - ;;=> ["SELECT a, b AS c, D(e), F(g) AS h"] - +user=> (sql/format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) +;; select a (column), b (aliased to c), d (fn call), f (fn call, aliased to h): +["SELECT a, b AS c, D(e), F(g) AS h"] ``` On a related note, `sql/call` has been removed because it should never be needed now: `[:foo ...]` should always be treated as a function call, consistently, avoiding the special cases in v1 that necessitated the explicit `sql/call` syntax. The `:set` clause is dialect-dependent. In `:mysql`, it is ranked just before the `:where` clause. In all other dialects, it is ranked just before the `:from` clause. Accordingly, the `:set0` and `:set1` clauses are no longer supported (because they were workarounds in 1.x for this conflict). +HoneySQL 1.x implemented `:exists` as part of the DSL, which was incorrect: +it should have been a function, and in 2.x it is: + +```clojure +;; 1.x: EXISTS should never have been implemented as SQL syntax: it's an operator! +;; (sq/format {:exists {:select [:a] :from [:foo]}}) +;;=> ["EXISTS (SELECT a FROM foo)"])) + +;; 2.x: select function call with an alias: +user=> (sql/format {:select [[[:exists {:select [:a] :from [:foo]}] :x]]}) +["SELECT EXISTS (SELECT a FROM foo) AS x"])) +``` + ## Extensibility The protocols and multimethods in 1.x have all gone away. The primary extension point is `honey.sql/register-clause!` which lets you specify the new clause (keyword), the formatter function for it, and the existing clause that it should be ranked before (`format` processes the DSL in clause order). From 63add4df3ba930d4b2dd33872a32a414636e0fb7 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 14:21:54 -0800 Subject: [PATCH 157/254] Clean up differences code --- doc/differences-from-1-x.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index b591f79..ded25b3 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -136,11 +136,11 @@ it should have been a function, and in 2.x it is: ```clojure ;; 1.x: EXISTS should never have been implemented as SQL syntax: it's an operator! ;; (sq/format {:exists {:select [:a] :from [:foo]}}) -;;=> ["EXISTS (SELECT a FROM foo)"])) +;;=> ["EXISTS (SELECT a FROM foo)"] ;; 2.x: select function call with an alias: user=> (sql/format {:select [[[:exists {:select [:a] :from [:foo]}] :x]]}) -["SELECT EXISTS (SELECT a FROM foo) AS x"])) +["SELECT EXISTS (SELECT a FROM foo) AS x"] ``` ## Extensibility From ea4e120252a3172a3cd2fc0f80e5cdd2c73008c5 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 16:52:35 -0800 Subject: [PATCH 158/254] Add docstrings for DDL helpers --- src/honey/sql/helpers.cljc | 99 +++++++++++++++++++++++++++++++++++--- 1 file changed, 91 insertions(+), 8 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 2620056..b3ba6b4 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -48,46 +48,121 @@ ;; for every clause, there is a public helper (defn alter-table + "Alter table takes a SQL entity (the name of the + table to modify) and any number of optional SQL + clauses to be applied in a single statement. + + (alter-table :foo (add-column :id :int nil)) + + If only the SQL entity is provided, the result + needs to be combined with another SQL clause to + modify the table. + + (-> (alter-table :foo) (add-column :id :int nil))" + {:arglists '([table & clauses])} [& args] (generic :alter-table args)) (defn add-column - [& args] - (generic :add-column args)) + "Add a single column to a table (see `alter-table`). + + Accepts any number of SQL elements that describe + a column: + + (add-column :name [:varchar 32] [:not nil])" + [& col-elems] + (generic :add-column col-elems)) (defn drop-column + "Takes a single column name (use with `alter-table`). + + (alter-table :foo (drop-column :bar))" + {:arglists '([col])} [& args] (generic-1 :drop-column args)) (defn modify-column - [& args] - (generic :modify-column args)) + "Like add-column, accepts any number of SQL elements + that describe the new column definition: + + (modify-column :name [:varchar 64] [:not nil])" + [& col-elems] + (generic :modify-column col-elems)) (defn rename-column + "Accepts two column names: the original name and the + new name to which it should be renamed: + + (rename-column :name :full-name)" + {:arglists '([old-col new-col])} [& args] (generic :rename-column args)) (defn add-index + "Like add-column, this accepts any number of SQL + elements that describe a new index to be added: + + (add-index :unique :name-key :first-name :last-name) + + Produces: UNIQUE name_key(first_name, last_name)" + {:arglist '([& index-elems])} [& args] (generic :add-index args)) (defn drop-index + "Like drop-table, accepts a single index name: + + (drop-index :name-key)" [& args] (generic-1 :drop-index args)) (defn rename-table + "Accepts a single table name and, despite its name, + actually means RENAME TO: + + (alter-table :foo (rename-table :bar)) + + Produces: ALTER TABLE foo RENAME TO bar" + {:arglist '([new-table])} [& args] (generic-1 :rename-table args)) (defn create-table + "Accepts a table name to create and optionally a + flag to trigger IF NOT EXISTS in the SQL: + + (create-table :foo) + (create-table :foo :if-not-exists) + + That second argument can be truthy value but using + that keyword is recommended for clarity." + {:arglists '([table] [table if-not-exists])} [& args] (generic :create-table args)) (defn create-extension + "Accepts an extension name to create and optionally a + flag to trigger IF NOT EXISTS in the SQL: + + (create-extension :postgis) + (create-extension :postgis :if-not-exists) + + That second argument can be truthy value but using + that keyword is recommended for clarity." + {:arglists '([extension] [extension if-not-exists])} [& args] (generic :create-extension args)) (defn with-columns + "Accepts any number of column descriptions. Each + column description is a sequence of SQL elements + that specify the name and the attributes. + + Can also accept a single argument which is a + collection of column descriptions (mostly for + compatibility with nilenso/honeysql-postgres + which used to be needed for DDL)." + {:arglists '([& col-specs] [col-spec-coll])} [& args] ;; special case so (with-columns [[:col-1 :definition] [:col-2 :definition]]) ;; also works in addition to (with-columns [:col-1 :definition] [:col-2 :definition]) @@ -99,16 +174,24 @@ (generic :with-columns args))) (defn create-view + "Accepts a single view name to create. + + (-> (create-view :cities) + (select :*) (from :city))" [& args] (generic-1 :create-view args)) (defn drop-table - [& args] - (generic :drop-table args)) + "Accepts one or more table names to drop. + + (drop-table :foo)" + [& tables] + (generic :drop-table tables)) (defn drop-extension - [& args] - (generic :drop-extension args)) + "Accepts one or more extension names to drop." + [& extensions] + (generic :drop-extension extensions)) (defn nest [& args] From f6a38e4024565f3160bb1d5e8cb3ec78e367488f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 17:20:24 -0800 Subject: [PATCH 159/254] More helper docstrings --- src/honey/sql/helpers.cljc | 61 ++++++++++++++++++++++++++++++-------- 1 file changed, 48 insertions(+), 13 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index b3ba6b4..29ef462 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -158,6 +158,13 @@ column description is a sequence of SQL elements that specify the name and the attributes. + (with-columns [:id :int [:not nil]] + [:name [:varchar 32] [:default \"\"]]) + + Produces: + id INT NOT NULL, + name VARCHAR(32) DEFAULT '' + Can also accept a single argument which is a collection of column descriptions (mostly for compatibility with nilenso/honeysql-postgres @@ -208,34 +215,60 @@ ;; these five need to supply an empty hash map since they wrap ;; all of their arguments: (defn intersect - [& args] - (generic :intersect (cons {} args))) + "Accepts any number of SQL clauses (queries) on + which to perform a set intersection." + [& clauses] + (generic :intersect (cons {} clauses))) (defn union - [& args] - (generic :union (cons {} args))) + "Accepts any number of SQL clauses (queries) on + which to perform a set union." + [& clauses] + (generic :union (cons {} clauses))) (defn union-all - [& args] - (generic :union-all (cons {} args))) + "Accepts any number of SQL clauses (queries) on + which to perform a set union all." + [& clauses] + (generic :union-all (cons {} clauses))) (defn except - [& args] - (generic :except (cons {} args))) + "Accepts any number of SQL clauses (queries) on + which to perform a set except." + [& clauses] + (generic :except (cons {} clauses))) (defn except-all - [& args] - (generic :except-all (cons {} args))) + "Accepts any number of SQL clauses (queries) on + which to perform a set except all." + [& clauses] + (generic :except-all (cons {} clauses))) (defn select - [& args] - (generic :select args)) + "Accepts any number of column names, or column/alias + pairs, or SQL expressions (optionally aliased): + + (select :id [:foo :bar] [[:max :quux]]) + + Produces: SELECT id, foo AS bar, MAX(quux)" + [& exprs] + (generic :select exprs)) (defn select-distinct + "Like `select` but produces SELECT DISTINCT." [& args] (generic :select-distinct args)) (defn select-distinct-on + "Accepts a sequence of one or more columns for the + distinct clause, followed by any number of column + names, or column/alias pairs, or SQL expressions + (optionally aliased), as for `select`: + + (select-distinct-on [:a :b] :c [:d :dd]) + + Produces: SELECT DISTINCT ON(a, b) c, d AS dd" + {:arglists '([distinct-cols & exprs])} [& args] (generic :select-distinct-on args)) @@ -256,8 +289,10 @@ (generic :delete-from args)) (defn truncate + "Accepts a single table name to truncate." + {:arglists '([table])} [& args] - (generic :truncate args)) + (generic-1 :truncate args)) (defn columns [& args] From 9ec447109f73efca6f0f63f782e99fe44d770430 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 17:54:00 -0800 Subject: [PATCH 160/254] Oracle dialect suppresses AS --- doc/getting-started.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 09d3865..63a0048 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -245,7 +245,7 @@ The most visible difference between dialects is how SQL entities should be quoted (if the `:quoted true` option is provided to `format`). Most databases use `"` for quoting (the `:ansi` and `:oracle` dialects). The `:sqlserver` dialect uses `[`..`]` and the `:mysql` dialect uses -```..```. +```..```. In addition, the `:oracle` dialect disables `AS` in aliases. Currently, the only dialect that has substantive differences from the others is `:mysql` which has a `:lock` clause (that is very From d5ab2a8d8c4d84192cd932783518dbcb2b6fc478 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 17:54:13 -0800 Subject: [PATCH 161/254] More helper docstrings --- src/honey/sql/helpers.cljc | 98 +++++++++++++++++++++++++++++++++----- 1 file changed, 87 insertions(+), 11 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 29ef462..ea6cf1b 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -250,7 +250,11 @@ (select :id [:foo :bar] [[:max :quux]]) - Produces: SELECT id, foo AS bar, MAX(quux)" + Produces: SELECT id, foo AS bar, MAX(quux) + + The special column name :* produces * for 'all columns'. + You can also specify :t.* for 'all columns' from the + table (or alias) t." [& exprs] (generic :select exprs)) @@ -295,16 +299,41 @@ (generic-1 :truncate args)) (defn columns - [& args] - (generic :columns args)) + "To be used with `insert-into` to specify the list of + column names for the insert operation. Accepts any number + of column names: + + (-> (insert-into :foo) + (columns :a :b :c) + (values [[1 2 3] [2 4 6]])) + + Produces: + INSERT INTO foo (a, b, c) VALUES (?, ?, ?), (?, ?, ?) + Parameters: 1 2 3 2 4 6" + [& cols] + (generic :columns cols)) (defn set + "Accepts a hash map specifying column names and the + values to be assigned to them, as part of `update`: + + (-> (update :foo) + (set {:a 1 :b nil})) + + Produces: UPDATE foo SET a = ?, b = NULL" + {:arglists '([col-set-map])} [& args] (generic-1 :set args)) (defn from - [& args] - (generic :from args)) + "Accepts one or more table names, or table/alias pairs. + + (-> (select :*) + (from [:foo :bar])) + + Produces: SELECT * FROM foo AS bar" + [& tables] + (generic :from tables)) (defn using [& args] @@ -339,16 +368,30 @@ (generic :cross-join args)) (defn where - [& args] - (generic :where args)) + "Accepts one or more SQL expressions (conditions) and + combines them with AND: + + (where [:= :status 0] [:<> :task \"backup\"]) + + Produces: WHERE (status = ?) AND (task <> ?) + Parameters: 0 \"backup\"" + [& exprs] + (generic :where exprs)) (defn group-by [& args] (generic :group-by args)) (defn having - [& args] - (generic :having args)) + "Like `where`, accepts one or more SQL expressions + (conditions) and combines them with AND: + + (having [:> :count 0] [:<> :name nil]) + + Produces: HAVING (count > ?) AND (name IS NOT NULL) + Parameters: 0" + [& exprs] + (generic :having exprs)) (defn window [& args] @@ -363,10 +406,24 @@ (generic :order-by args)) (defn limit + "Specific to MySQL, accepts a single SQL expression: + + (limit 40) + + Produces: LIMIT ? + Parameters: 40" + {:arglists '([limit])} [& args] (generic-1 :limit args)) (defn offset + "Specific to MySQL, accepts a single SQL expression: + + (offset 10) + + Produces: OFFSET ? + Parameters: 10" + {:arglists '([offset])} [& args] (generic-1 :offset args)) @@ -375,6 +432,19 @@ (generic-1 :for args)) (defn values + "Accepts a single argument: a collection of row values. + Each row value can be either a sequence of column values + or a hash map of column name/column value pairs. + + Used with `insert-into`. + + (-> (insert-into :foo) + (values [{:id 1, :name \"John\"} + {:id 2, :name \"Fred\"}])) + + Produces: INSERT INTO foo (id, name) VALUES (?, ?), (?, ?) + Parameters: 1 \"John\" 2 \"Fred\"" + {:arglists '([row-value-coll])} [& args] (generic-1 :values args)) @@ -395,8 +465,14 @@ (generic :do-update-set args)) (defn returning - [& args] - (generic :returning args)) + "Accepts any number of column names to return from an + insert operation: + + (returning :*) + + Produces: RETURNING *" + [& cols] + (generic :returning cols)) ;; helpers that produce non-clause expressions -- must be listed below: (defn composite From 05360d10d6c4fb45621484360ad34c444d1226d4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 18:28:35 -0800 Subject: [PATCH 162/254] More helper docstrings --- src/honey/sql/helpers.cljc | 48 ++++++++++++++++++++++++++++++++++++++ 1 file changed, 48 insertions(+) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index ea6cf1b..d23c01a 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -476,16 +476,64 @@ ;; helpers that produce non-clause expressions -- must be listed below: (defn composite + "Accepts any number of SQL expressions and produces + a composite value from them: + + (composite :a 42) + + Produces: (a, ?) + Parameters: 42" [& args] (into [:composite] args)) ;; to make this easy to use in a select, wrap it so it becomes a function: (defn over + "Accepts any number of OVER clauses, each of which + is a pair of an aggregate function and a window function + or a triple of an aggregate function, a window function, + and an alias: + + (select :id (over [[:avg :salary] (partition-by :department)])) + + Produces: SELECT id, AVG(salary) OVER ()PARTITION BY department)" [& args] [(into [:over] args)]) ;; this helper is intended to ease the migration from nilenso: (defn upsert + "Provided purely to ease migration from nilenso/honeysql-postgres + this accepts a single clause, constructed from on-conflict, + do-nothing or do-update-set, and where. Any of those are optional. + + This helper unpacks that clause and turns it into what HoneySQL + 2.x expects, with any where clause being an argument to the + do-update-set helper, along with the `:fields`. + + nilenso/honeysql-postgres: + + (-> ... + (upsert (-> (on-conflict :col) + do-nothing))) + (-> ... + (upsert (-> (on-conflict :col) + (do-update-set :x) + (where [:<> :x nil])))) + + HoneySQL 2.x: + + (-> ... + (on-conflict :col) + do-nothing) + (-> ... + (on-conflict :col) + (do-update-set {:fields [:x] + :where [:<> :x nil]})) + + Alternative structure for that second one: + + (-> ... + (on-conflict :col) + (do-update-set :x {:where [:<> :x nil]}))" ([clause] (upsert {} clause)) ([data clause] (let [{:keys [on-conflict do-nothing do-update-set where]} clause] From f4137d3fc1ecb57ddb95e7bac911aa75b97b9756 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 20:39:32 -0800 Subject: [PATCH 163/254] Enhance insert-into; document more helpers --- src/honey/sql/helpers.cljc | 31 +++++++++++++++++++++++++++++-- test/honey/sql/helpers_test.cljc | 6 ++++++ 2 files changed, 35 insertions(+), 2 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index d23c01a..ae719fd 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -277,18 +277,45 @@ (generic :select-distinct-on args)) (defn insert-into + "Accepts a table name or a table/alias pair. That + can optionally be followed by a collection of + column names. That can optionally be followed by + a (select) statement clause. + + (insert-into :table) + (insert-into [:table :t]) + (insert-into :table [:id :name :cost]) + (insert-into :table (-> (select :*) (from :other))) + (insert-into [:table :t] + [:id :name :cost] + (-> (select :*) (from :other)))" + {:arglists '([table] [table cols] [table statement] [table cols statement])} [& args] - (generic :insert-into args)) + (let [[table cols statement] args] + (if (and (sequential? cols) (map? statement)) + (generic :insert-into [[table cols] statement]) + (generic :insert-into args)))) (defn update + "Accepts either a table name or a table/alias pair. + + (-> (update :table) (set {:id 1 :cost 32.1}))" [& args] - (generic :update args)) + (generic-1 :update args)) (defn delete + "For deleting from multiple tables. + Accepts a collection of table names to delete from. + + (-> (delete [:films :directors]) (where [:= :id 1]))" [& args] (generic-1 :delete args)) (defn delete-from + "For deleting from a single table. + Accepts a single table name to delete from. + + (-> (delete-from :films) (where [:= :id 1]))" [& args] (generic :delete-from args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index b1063d5..35274e7 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -473,4 +473,10 @@ ["INSERT INTO transport (id, name) SELECT * FROM cars"])) ;; with an alias and columns: (is (= (sql/format (insert-into ['(transport t) '(id, name)] '{select (*) from (cars)})) + ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"])) + ;; three arguments with columns: + (is (= (sql/format (insert-into :transport [:id :name] '{select (*) from (cars)})) + ["INSERT INTO transport (id, name) SELECT * FROM cars"])) + ;; three arguments with an alias and columns: + (is (= (sql/format (insert-into '(transport t) '(id, name) '{select (*) from (cars)})) ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"]))) From 0bb7740f697b58da9e394c5f7ad2ec5abed04bf8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 14 Feb 2021 20:45:14 -0800 Subject: [PATCH 164/254] Docstrings --- src/honey/sql/helpers.cljc | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index ae719fd..bb30f37 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -300,6 +300,7 @@ "Accepts either a table name or a table/alias pair. (-> (update :table) (set {:id 1 :cost 32.1}))" + {:arglists '([table])} [& args] (generic-1 :update args)) @@ -308,6 +309,7 @@ Accepts a collection of table names to delete from. (-> (delete [:films :directors]) (where [:= :id 1]))" + {:arglists '([table-coll])} [& args] (generic-1 :delete args)) @@ -316,6 +318,7 @@ Accepts a single table name to delete from. (-> (delete-from :films) (where [:= :id 1]))" + {:arglists '([table])} [& args] (generic :delete-from args)) @@ -480,10 +483,14 @@ (generic-1 :on-conflict args)) (defn on-constraint + "Accepts a single constraint name." + {:arglists '([constraint])} [& args] (generic :on-constraint args)) (defn do-nothing + "Called with no arguments, produces DO NOTHING" + {:arglists '([])} [& args] (generic :do-nothing args)) From 0b687c5eb0aa00007c3d2f90f474598390f28fa8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 16:27:08 -0800 Subject: [PATCH 165/254] Add nilenso version of tests for comparison This shows all the changes side-by-side. --- test/honey/sql/postgres_test.cljc | 60 +++++++++++++++++++++++++------ 1 file changed, 49 insertions(+), 11 deletions(-) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 3c2058b..6e806ce 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -34,6 +34,7 @@ (deftest upsert-test (testing "upsert sql generation for postgresql" (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + ;; preferred in honeysql: (-> (insert-into :distributors) (values [{:did 5 :dname "Gizmo Transglobal"} {:did 6 :dname "Associated Computing, Inc"}]) @@ -42,6 +43,7 @@ (returning :*) sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] + ;; identical to nilenso version: (-> (insert-into :distributors) (values [{:did 5 :dname "Gizmo Transglobal"} {:did 6 :dname "Associated Computing, Inc"}]) @@ -50,26 +52,31 @@ (returning :*) sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] + ;; preferred in honeysql: (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (on-conflict :did) do-nothing sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" 7 "Redline GmbH"] + ;; identical to nilenso version: (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (upsert (-> (on-conflict :did) do-nothing)) sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + ;; preferred in honeysql: (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) (on-conflict (on-constraint :distributors_pkey)) do-nothing sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + ;; almost identical to nilenso version: (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) + ;; in nilenso, this was (on-conflict-constraint :distributors_pkey) (upsert (-> (on-conflict (on-constraint :distributors_pkey)) do-nothing)) sql/format))) @@ -77,22 +84,33 @@ (sql/format {:insert-into :distributors :values [{:did 10 :dname "Pinp Design"} {:did 11 :dname "Foo Bar Works"}] + ;; in nilenso, these two were a submap under :upsert :on-conflict :did :do-update-set :dname}))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname || ? || d.dname || ?" 23 "Foo Distributors" " (formerly " ")"] (-> (insert-into :distributors) (values [{:did 23 :dname "Foo Distributors"}]) (on-conflict :did) + ;; nilenso: #_(do-update-set! [:dname "EXCLUDED.dname || ' (formerly ' || d.dname || ')'"]) + ;; honeysql (do-update-set {:dname [:|| :EXCLUDED.dname " (formerly " :d.dname ")"]}) sql/format))) (is (= ["INSERT INTO distributors (did, dname) SELECT ?, ? ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 1 "whatever"] - (-> (insert-into [:distributors [:did :dname]] + ;; honeysql version: + (-> (insert-into :distributors + [:did :dname] (select 1 "whatever")) - #_(query-values (select 1 "whatever")) - (upsert (-> (on-conflict (on-constraint :distributors_pkey)) - do-nothing)) - sql/format))))) + (on-conflict (on-constraint :distributors_pkey)) + do-nothing + sql/format) + ;; nilenso version: + #_(-> (insert-into :distributors) + (columns :did :dname) + (query-values (select 1 "whatever")) + (upsert (-> (on-conflict-constraint :distributors_pkey) + do-nothing)) + sql/format))))) (deftest upsert-where-test (is (= ["INSERT INTO user (phone, name) VALUES (?, ?) ON CONFLICT (phone) WHERE phone IS NOT NULL DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name WHERE user.active = FALSE" "5555555" "John"] @@ -102,7 +120,18 @@ :on-conflict [:phone {:where [:<> :phone nil]}] :do-update-set {:fields [:phone :name] - :where [:= :user.active false]}})))) + :where [:= :user.active false]}}) + ;; nilenso version + #_(sql/format + {:insert-into :user + :values [{:phone "5555555" :name "John"}] + ;; nested under :upsert + :upsert {:on-conflict [:phone] + ;; but :where is at the same level as :on-conflict + :where [:<> :phone nil] + ;; this is the same as in honeysql: + :do-update-set {:fields [:phone :name] + :where [:= :user.active false]}}})))) (deftest returning-test (testing "returning clause in sql generation for postgresql" @@ -135,6 +164,7 @@ (sql/format (drop-table :cities :towns :vilages)))))) (deftest create-table-test + ;; the nilenso versions of these tests required sql/call for function-like syntax (testing "create table with two columns" (is (= ["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"] (-> (create-table :cities) @@ -188,14 +218,15 @@ (deftest over-test (testing "window function over on select statemt" (is (= ["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] + ;; honeysql treats over as a function: (-> (select :id - ;; honeysql treats over as a function: (over [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] [[:max :salary] :w :MaxSalary])) (from :employee) (window :w (partition-by :department)) sql/format) + ;; nilenso treated over as a clause #_(-> (select :id) (over [[:avg :salary] (-> (partition-by :department) (order-by [:designation])) :Average] @@ -229,13 +260,16 @@ (deftest insert-into-with-alias (testing "insert into with alias" (is (= ["INSERT INTO distributors AS d (did, dname) VALUES (?, ?), (?, ?) ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname WHERE d.zipcode <> ? RETURNING d.*" 5 "Gizmo Transglobal" 6 "Associated Computing, Inc" "21201"] - (-> #_(insert-into-as :distributors :d) - (insert-into :distributors :d) + ;; honeysql supports alias in insert-into: + (-> (insert-into :distributors :d) + ;; nilensor required insert-into-as: + #_(insert-into-as :distributors :d) (values [{:did 5 :dname "Gizmo Transglobal"} {:did 6 :dname "Associated Computing, Inc"}]) (on-conflict :did) - (do-update-set (-> {:fields [:dname]} - (where [:<> :d.zipcode "21201"]))) + ;; honeysql supports names and a where clause: + (do-update-set :dname (where [:<> :d.zipcode "21201"])) + ;; nilenso nested those under upsert: #_(upsert (-> (on-conflict :did) (do-update-set :dname) (where [:<> :d.zipcode "21201"]))) @@ -305,15 +339,18 @@ (deftest select-distinct-on-test (testing "select distinct on" (is (= ["SELECT DISTINCT ON(\"a\", \"b\") \"c\" FROM \"products\""] + ;; honeysql has select-distinct-on: (-> (select-distinct-on [:a :b] :c) (from :products) (sql/format {:quoted true})) + ;; nilenso handled that via modifiers: #_(-> (select :c) (from :products) (modifiers :distinct-on :a :b) (sql/format :quoting :ansi)))))) (deftest create-extension-test + ;; previously, honeysql required :allow-dashed-names? true (testing "create extension" (is (= ["CREATE EXTENSION \"uuid-ossp\""] (-> (create-extension :uuid-ossp) @@ -324,6 +361,7 @@ (sql/format {:quoted true})))))) (deftest drop-extension-test + ;; previously, honeysql required :allow-dashed-names? true (testing "create extension" (is (= ["DROP EXTENSION \"uuid-ossp\""] (-> (drop-extension :uuid-ossp) From c0dfdad19b3fbf47e16a1703df925e47a9ffc5c6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 16:37:00 -0800 Subject: [PATCH 166/254] Add modifiers to differences --- doc/differences-from-1-x.md | 18 ++++++++++++++++-- 1 file changed, 16 insertions(+), 2 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index ded25b3..1103da9 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -93,7 +93,7 @@ The following options are no longer supported: ## DSL Changes -The general intent is that the data structure behind the DSL is unchanged, for the most part. The only deliberate change is the removal of the reader literals (and their associated helper functions) in favor of standardized syntax, e.g., `[:array [1 2 3]]` instead of either `#sql/array [1 2 3]` or `(sql/array [1 2 3])`. +The general intent is that the data structure behind the DSL is unchanged, for the most part. The main deliberate change is the removal of the reader literals (and their associated helper functions) in favor of standardized syntax, e.g., `[:array [1 2 3]]` instead of either `#sql/array [1 2 3]` or `(sql/array [1 2 3])`. The following new syntax has been added: @@ -118,6 +118,8 @@ definitions in `CREATE TABLE` clauses, now that v2 supports DDL statement construction: `:constraint`, `:foreign-key`, `:index`, `:primary-key`, `:references`, `:unique`, and -- as noted above -- `:default`. +### select and function calls + You can now `SELECT` a function call more easily, using `[[...]]`. This was previously an error -- missing an alias -- but it was a commonly requested change, to avoid using `(sql/call ...)`: ```clojure @@ -128,7 +130,19 @@ user=> (sql/format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) On a related note, `sql/call` has been removed because it should never be needed now: `[:foo ...]` should always be treated as a function call, consistently, avoiding the special cases in v1 that necessitated the explicit `sql/call` syntax. -The `:set` clause is dialect-dependent. In `:mysql`, it is ranked just before the `:where` clause. In all other dialects, it is ranked just before the `:from` clause. Accordingly, the `:set0` and `:set1` clauses are no longer supported (because they were workarounds in 1.x for this conflict). +### select modifiers + +HoneySQL 1.x provided a `:modifiers` clause (and a `modifiers`) helper as a way to "modify" +a `SELECT` to be `DISTINCT`. nilenso/honeysql-helpers extended that to support `:distinct-on` +a group of columns. In HoneySQL 2.x, you use `:select-distinct` and `:select-distinct-on` +(and their associated helpers) for that instead. + +### set vs sset, set0, set1 + +The `:set` clause is dialect-dependent. In `:mysql`, it is ranked just before the `:where` clause. In all other dialects, it is ranked just before the `:from` clause. Accordingly, the `:set0` and `:set1` clauses are no longer supported (because they were workarounds in 1.x for this conflict). The helper is now called +`set` rather than `sset`, `set0`, and `set1` (so be aware of the conflict with `clojure.core/set`). + +### exists HoneySQL 1.x implemented `:exists` as part of the DSL, which was incorrect: it should have been a function, and in 2.x it is: From 155ae25ad06bce43fdef3594b87ae71ee40915e3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 17:56:18 -0800 Subject: [PATCH 167/254] Clean up create extension test --- test/honey/sql/postgres_test.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 6e806ce..6074fd5 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -357,7 +357,7 @@ (sql/format {:quoted true}))))) (testing "create extension if not exists" (is (= ["CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\""] - (-> (create-extension :uuid-ossp :if-not-exists? true) + (-> (create-extension :uuid-ossp :if-not-exists) (sql/format {:quoted true})))))) (deftest drop-extension-test From 331597b22b5fc9cf3679d6e8f795d8ced93c1514 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 17:56:47 -0800 Subject: [PATCH 168/254] Improve on conflict on constraint syntax --- src/honey/sql.cljc | 4 ++++ src/honey/sql/helpers.cljc | 6 ++++-- 2 files changed, 8 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3c86e63..f45d527 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -503,6 +503,10 @@ " (" (format-entity (first x)) ") " sql)] params)) + (and (sequential? x) (= 1 (count x))) + (format-on-conflict k (first x)) + (and (sequential? x) (= 0 (count x))) + [(sql-kw k)] :else (throw (ex-info "unsupported :on-conflict format" {:clause x})))) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index bb30f37..f23d7e8 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -480,7 +480,7 @@ (defn on-conflict [& args] - (generic-1 :on-conflict args)) + (generic :on-conflict args)) (defn on-constraint "Accepts a single constraint name." @@ -570,10 +570,12 @@ (do-update-set :x {:where [:<> :x nil]}))" ([clause] (upsert {} clause)) ([data clause] - (let [{:keys [on-conflict do-nothing do-update-set where]} clause] + (let [{:keys [on-conflict on-constraint do-nothing do-update-set where]} clause] (cond-> data on-conflict (assoc :on-conflict on-conflict) + on-constraint + (assoc :on-constraint on-constraint) do-nothing (assoc :do-nothing do-nothing) do-update-set From 2f424e02582bb70d2d60d6ac6b5c057b8622e2ca Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 17:57:07 -0800 Subject: [PATCH 169/254] Add a big chunk of Postgres/nilenso docs --- doc/getting-started.md | 4 +- doc/postgresql.md | 288 ++++++++++++++++++++++++++++++++++++++++- 2 files changed, 289 insertions(+), 3 deletions(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 63a0048..4fd0179 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -276,7 +276,9 @@ specify a dialect in the `format` call, you can specify ``` Out of the box, as part of the extended ANSI SQL support, -HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md) +HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md). + +> Note: the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library out of the box! ## Format Options diff --git a/doc/postgresql.md b/doc/postgresql.md index e509f07..00fce7a 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -1,4 +1,288 @@ # PostgreSQL Support -This section will document the PostgreSQL-specific -features that HoneySQL supports out of the box. +This section covers the PostgreSQL-specific +features that HoneySQL supports out of the box +for which you previously needed the +[nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres). + +Everything that the nilenso library provided is implemented +directly in HoneySQL 2.x although a few things have a +slightly different syntax. + +## Upsert + +Upserting data is relatively easy in PostgreSQL +because of the `ON CONFLICT`, `ON CONSTRAINT`, +`DO NOTHING`, and `DO UPDATE SET` parts of the +`INSERT` statement. + +This usage is supported identically to the nilenso library: + +```clojure +user=> (-> (insert-into :distributors) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (upsert (-> (on-conflict :did) + (do-update-set :dname))) + (returning :*) + sql/format) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) + ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" + 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] +``` + +However, the nested `upsert` helper is no longer needed +(and there is no corresponding `:upsert` clause in the DSL): + +```clojure +user=> (-> (insert-into :distributors) + (values [{:did 5 :dname "Gizmo Transglobal"} + {:did 6 :dname "Associated Computing, Inc"}]) + (on-conflict :did) + (do-update-set :dname) + (returning :*) + sql/format) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?), (?, ?) + ON CONFLICT (did) DO UPDATE SET dname = EXCLUDED.dname RETURNING *" + 5 "Gizmo Transglobal" 6 "Associated Computing, Inc"] +``` + +Similarly, the `do-nothing` helper behaves just the same +as in the nilenso library: + +```clojure +user=> (-> (insert-into :distributors) + (values [{:did 7 :dname "Redline GmbH"}]) + (upsert (-> (on-conflict :did) + do-nothing)) + sql/format))) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?) + ON CONFLICT (did) DO NOTHING" + 7 "Redline GmbH"] +``` + +As above, the nested `upsert` helper is no longer needed: + +```clojure +user=> (-> (insert-into :distributors) + (values [{:did 7 :dname "Redline GmbH"}]) + (on-conflict :did) + do-nothing + sql/format))) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?) + ON CONFLICT (did) DO NOTHING" + 7 "Redline GmbH"] +``` + +`ON CONSTRAINT` is handled slightly differently to the nilenso library: + +```clojure +user=> (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + ;; nilenso used (on-conflict-constraint :distributors_pkey) here: + (on-conflict (on-constraint :distributors_pkey)) + do-nothing + sql/format))) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?) + ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" + 9 "Antwerp Design"] +``` + +As above, the `upsert` helper has been omitted here. + +An upsert with where clauses is also possible, with a +more compact syntax than the nilenso library used: + +```clojure +user=> (-> (insert-into :user) + (values [{:phone "5555555" :name "John"}]) + (on-conflict :phone (where [:<> :phone nil])) + (do-update-set :phone :name (where [:= :user.active false])) + sql/format) +;; newlines inserted for readability: +["INSERT INTO user (phone, name) VALUES (?, ?) + ON CONFLICT (phone) WHERE phone IS NOT NULL + DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name + WHERE user.active = FALSE" "5555555" "John"] +;; using the DSL directly: +user=> (sql/format + {:insert-into :user + :values [{:phone "5555555" :name "John"}] + :on-conflict [:phone + {:where [:<> :phone nil]}] + :do-update-set {:fields [:phone :name] + :where [:= :user.active false]}}) +;; newlines inserted for readability: +["INSERT INTO user (phone, name) VALUES (?, ?) + ON CONFLICT (phone) WHERE phone IS NOT NULL + DO UPDATE SET phone = EXCLUDED.phone, name = EXCLUDED.name + WHERE user.active = FALSE" "5555555" "John"] +``` + +By comparison, this is the DSL structure that nilenso would have required: + +```clojure + ;; NOT VALID FOR HONEYSQL! + {:insert-into :user + :values [{:phone "5555555" :name "John"}] + ;; nested under :upsert + :upsert {:on-conflict [:phone] + ;; but :where is at the same level as :on-conflict + :where [:<> :phone nil] + ;; this is the same as in honeysql: + :do-update-set {:fields [:phone :name] + :where [:= :user.active false]}}} +``` + +## INSERT INTO AS + +## Returning + +The `RETURNING` clause is supported identically to the nilenso library: + +```clojure +;; via the DSL: +user=> (sql/format {:delete-from :distributors + :where [:> :did 10] + :returning [:*]}) +["DELETE FROM distributors WHERE did > ? RETURNING *" 10] +;; via the helpers: +user=> (-> (update :distributors) + (set {:dname "Foo Bar Designs"}) + (where [:= :did 2]) + (returning [:did :dname]) + sql/format) +["UPDATE distributors SET dname = ? WHERE did = ? RETURNING did dname" + "Foo Bar Designs" 2] +``` + +## DDL Support + +The following DDL statements are all supported by HoneySQL +(these are mostly not PostgreSQL-specific but they were not +supported by HoneySQL 1.x): + +* `CREATE VIEW` +* `CREATE TABLE` +* `DROP TABLE` +* `ALTER TABLE` + +These are mostly identical to what the nilenso library provides +except that `sql/call` is never needed -- you can use the direct +`[:func ..]` function call syntax instead: + +```clojure +;; create view: +user=> (-> (create-view :metro) + (select :*) + (from :cities) + (where [:= :metroflag "Y"]) + sql/format) +["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "Y"] +;; create table: +user=> (-> (create-table :cities) + (with-columns [[:city [:varchar 80] [:primary-key]] + [:location :point]]) + sql/format) +;; values are inlined: +["CREATE TABLE cities (city VARCHAR(80) PRIMARY KEY, location POINT)"] +;; default values for columns: +user=> (-> (create-table :distributors) + (with-columns [[:did :integer [:primary-key] + ;; "serial" is inlined as 'SERIAL': + [:default [:nextval "serial"]]] + [:name [:varchar 40] [:not nil]]]) + sql/format) +;; newlines inserted for readability: +["CREATE TABLE distributors ( + did INTEGER PRIMARY KEY DEFAULT NEXTVAL('SERIAL'), + name VARCHAR(40) NOT NULL +)"] +;; PostgreSQL CHECK constraint is supported: +user=> (-> (create-table :products) + (with-columns [[:product_no :integer] + [:name :text] + [:price :numeric [:check [:> :price 0]]] + [:discounted_price :numeric] + [[:check [:and [:> :discounted_price 0] [:> :price :discounted_price]]]]]) + sql/format) +;; newlines inserted for readability: +["CREATE TABLE products ( + product_no INTEGER, + name TEXT, + price NUMERIC CHECK(PRICE > 0), + discounted_price NUMERIC, + CHECK((discounted_price > 0) AND (price > discounted_price)) +)"] +;; conditional creation: +user=> (-> (create-table :products :if-not-exists) + ... + sql/format) +["CREATE TABLE IF NOT EXISTS products (...)"] +;; drop table: +user=> (sql/format (drop-table :cities)) +["DROP TABLE cities"] +;; drop multiple tables: +user=> (sql/format (drop-table :cities :towns :vilages)) +["DROP TABLE cities, towns, vilages"] +;; conditional drop: +user=> (sql/format (drop-table :if-exists :cities :towns :vilages)) +["DROP TABLE IF EXISTS cities, towns, vilages"] +;; alter table add column: + +;; alter table drop column: + +;; alter table modify column: + +;; alter table rename column: + +;; rename table: + +``` + +The following PostgreSQL-specific DDL statements are supported +(with the same syntax as the nilenso library but `sql/format` +takes slightly different options): + +```clojure +;; create extension: +user=> (-> (create-extension :uuid-ossp) + (sql/format {:quoted true})) +;; quoting is required for a name containing a hyphen: +["CREATE EXTENSION \"uuid-ossp\""] +;; conditional creation: +user=> (-> (create-extension :uuid-ossp :if-not-exists) + (sql/format {:quoted true})) +["CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\""] +;; drop extension: +user=> (-> (drop-extension :uuid-ossp) + (sql/format {:quoted true})) +["DROP EXTENSION \"uuid-ossp\""] +;; drop multiple extensions: +user=> (-> (drop-extension :uuid-ossp :postgis) + (sql/format {:quoted true})) +["DROP EXTENSION \"uuid-ossp\", \"postgis\""] +;; conditional drop: +user=> (-> (drop-extension :if-exists :uuid-ossp :postgis) + (sql/format {:quoted true})) +["DROP EXTENSION IF EXISTS \"uuid-ossp\", \"postgis\""] +``` + +In addition, HoneySQL supports these DDL statements that were +not supported by the nilenso library: + +```clojure +;; alter table add index: + +;; alter table drop index: + +;; alter table with multiple clauses: + +``` + +## Window / Partition Support \ No newline at end of file From 28a4074e12a2292f01763ac8b28aca4c4df578c0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 20:43:53 -0800 Subject: [PATCH 170/254] Add flexibility for on conflict / on constraint --- doc/clause-reference.md | 9 +++++++++ doc/postgresql.md | 19 +++++++++++++++---- src/honey/sql/helpers.cljc | 2 +- test/honey/sql_test.cljc | 15 +++++++++++++++ 4 files changed, 40 insertions(+), 5 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 8b3cc38..09aaca6 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -633,6 +633,8 @@ of a SQL entity and a SQL clause. The SQL entity is a column name and the SQL clause can be an `:on-constraint` clause or a`:where` clause. +_[For convenience of use with the `on-conflict` helper, this clause can also accept any of those arguments, wrapped in a sequence; it can also accept an empty sequence, and just produce `ON CONFLICT`, so that it can be combined with other clauses directly]_ + `:on-constraint` accepts a single SQL entity that identifies a constraint name. @@ -676,6 +678,13 @@ user=> (sql/format {:insert-into :companies :on-conflict {:on-constraint :name-idx} :do-nothing true}) ["INSERT INTO companies (name) VALUES (?) ON CONFLICT ON CONSTRAINT name_idx DO NOTHING" "Microsoft"] +;; empty :on-conflict combined with :on-constraint clause: +user=> (sql/format {:insert-into :companies + :values [{:name "Microsoft"}] + :on-conflict [] + :on-constraint :name-idx + :do-nothing true}) +["INSERT INTO companies (name) VALUES (?) ON CONFLICT ON CONSTRAINT name_idx DO NOTHING" "Microsoft"] ``` ## returning diff --git a/doc/postgresql.md b/doc/postgresql.md index 00fce7a..d5c2892 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -57,7 +57,7 @@ user=> (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (upsert (-> (on-conflict :did) do-nothing)) - sql/format))) + sql/format) ;; newlines inserted for readability: ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" @@ -71,7 +71,7 @@ user=> (-> (insert-into :distributors) (values [{:did 7 :dname "Redline GmbH"}]) (on-conflict :did) do-nothing - sql/format))) + sql/format) ;; newlines inserted for readability: ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) DO NOTHING" @@ -86,7 +86,18 @@ user=> (-> (insert-into :distributors) ;; nilenso used (on-conflict-constraint :distributors_pkey) here: (on-conflict (on-constraint :distributors_pkey)) do-nothing - sql/format))) + sql/format) +;; newlines inserted for readability: +["INSERT INTO distributors (did, dname) VALUES (?, ?) + ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" + 9 "Antwerp Design"] +user=> (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + ;; nilenso used (on-conflict-constraint :distributors_pkey) here: + on-conflict + (on-constraint :distributors_pkey) + do-nothing + sql/format) ;; newlines inserted for readability: ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" @@ -285,4 +296,4 @@ not supported by the nilenso library: ``` -## Window / Partition Support \ No newline at end of file +## Window / Partition Support diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index f23d7e8..bae9616 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -486,7 +486,7 @@ "Accepts a single constraint name." {:arglists '([constraint])} [& args] - (generic :on-constraint args)) + (generic-1 :on-constraint args)) (defn do-nothing "Called with no arguments, produces DO NOTHING" diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3ba5a5f..3337cd8 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -534,6 +534,21 @@ DO NOTHING INSERT INTO customers (name, email) VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT +ON CONSTRAINT customers_name_key +DO NOTHING +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict [] + :on-constraint :customers_name_key + :do-nothing true} + {:pretty true}))) + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') ON CONFLICT (name) DO NOTHING "] From df6095449564e7b89a6363c69a0948f21df25786 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Feb 2021 21:20:20 -0800 Subject: [PATCH 171/254] Document DDL support --- doc/getting-started.md | 11 ++++++++++ doc/postgresql.md | 50 ++++++++++++++++++++++++++++++++---------- 2 files changed, 50 insertions(+), 11 deletions(-) diff --git a/doc/getting-started.md b/doc/getting-started.md index 4fd0179..464fdaf 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -228,6 +228,17 @@ you need to consider this when referring symbols in from the `honey.sql.helpers` namespace: `for`, `group-by`, `partition-by`, `set`, and `update`. +## DDL Statements + +HoneySQL 1.x did not support any DDL statements. It was fairly +common for people to use the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) +to get DDL support, even if they didn't need the PostgreSQL-specific +extensions. That library does not work with HoneySQL 2.x but all +of the functionality from it has been incorporated +into HoneySQL now and is described in the [PostgreSQL](doc/postgresql.md) +section (because that covers all of the things that the nilenso +library supported and much of it was PostgreSQL-specific!). + ## Dialects By default, HoneySQL operates in ANSI SQL mode but it supports diff --git a/doc/postgresql.md b/doc/postgresql.md index d5c2892..2a9e535 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -78,12 +78,13 @@ user=> (-> (insert-into :distributors) 7 "Redline GmbH"] ``` -`ON CONSTRAINT` is handled slightly differently to the nilenso library: +`ON CONSTRAINT` is handled slightly differently to the nilenso library, +with provided a single `on-conflict-constraint` helper (and clause): ```clojure user=> (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) - ;; nilenso used (on-conflict-constraint :distributors_pkey) here: + ;; can specify as a nested clause... (on-conflict (on-constraint :distributors_pkey)) do-nothing sql/format) @@ -93,7 +94,7 @@ user=> (-> (insert-into :distributors) 9 "Antwerp Design"] user=> (-> (insert-into :distributors) (values [{:did 9 :dname "Antwerp Design"}]) - ;; nilenso used (on-conflict-constraint :distributors_pkey) here: + ;; ...or as two separate clauses on-conflict (on-constraint :distributors_pkey) do-nothing @@ -245,15 +246,30 @@ user=> (sql/format (drop-table :cities :towns :vilages)) user=> (sql/format (drop-table :if-exists :cities :towns :vilages)) ["DROP TABLE IF EXISTS cities, towns, vilages"] ;; alter table add column: - +user=> (-> (alter-table :fruit) + (add-column :skin [:varchar 16] nil) + sql/format) +["ALTER TABLE fruit ADD COLUMN skin VARCHAR(16) NULL"] ;; alter table drop column: - +user=> (-> (alter-table :fruit) + (drop-column :skin) + sql/format) +["ALTER TABLE fruit DROP COLUMN skin"] ;; alter table modify column: - +user=> (-> (alter-table :fruit) + (modify-column :name [:varchar 64] [:not nil]) + sql/format) +["ALTER TABLE fruit MODIFY COLUMN name VARCHAR(64) NOT NULL"] ;; alter table rename column: - +user=> (-> (alter-table :fruit) + (rename-column :cost :price) + sql/format) +["ALTER TABLE fruit RENAME COLUMN cost TO price"] ;; rename table: - +user=> (-> (alter-table :fruit) + (rename-table :vegetable) + sql/format) +["ALTER TABLE fruit RENAME TO vegetable"] ``` The following PostgreSQL-specific DDL statements are supported @@ -289,11 +305,23 @@ not supported by the nilenso library: ```clojure ;; alter table add index: - +user=> (-> (alter-table :fruit) + (add-index :unique :fruit-name :name) + sql/format) +["ALTER TABLE fruit ADD UNIQUE fruit_name(name)"] ;; alter table drop index: - +user=> (-> (alter-table :fruit) + (drop-index :fruit-name) + sql/format) +["ALTER TABLE fruit DROP INDEX fruit_name"] ;; alter table with multiple clauses: - +user=> (sql/format (alter-table :fruit + (add-column :skin [:varchar 16] nil) + (add-index :unique :fruit-name :name))) +;; newlines inserted for readability: +["ALTER TABLE fruit + ADD COLUMN skin VARCHAR(16) NULL, + ADD UNIQUE fruit_name(name)"] ``` ## Window / Partition Support From cef11a761d2d356472437158d288a8e350e053ee Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 16 Feb 2021 11:42:56 -0800 Subject: [PATCH 172/254] Prep for 2.0.0-alpha2 --- CHANGELOG.md | 3 +++ 1 file changed, 3 insertions(+) diff --git a/CHANGELOG.md b/CHANGELOG.md index 5a611b2..26876b6 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.0-alpha2 (for early testing) + * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. + * Numerous small improvements have been made to clauses and helpers around insert/upsert. * 2.0.0-alpha1 (for early testing) * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. From b0782b93dd3cf78f59f6053f394f3cc631b87b83 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 16 Feb 2021 11:43:18 -0800 Subject: [PATCH 173/254] Prep for 2.0.0-alpha2 --- README.md | 4 ++-- doc/getting-started.md | 8 ++++---- pom.xml | 4 ++-- 3 files changed, 8 insertions(+), 8 deletions(-) diff --git a/README.md b/README.md index 9f1ceb1..c982b6b 100644 --- a/README.md +++ b/README.md @@ -12,11 +12,11 @@ This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINO Prerelease builds of the upcoming 2.x version of HoneySQL will soon be available: -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha1)](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1) +[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha2)](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha2) This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). -See this [summary of differences between v1 and v2](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/doc/differences-from-1-x) if you want to help test v2! +See this [summary of differences between v1 and v2](doc/differences-from-1-x.md) if you want to help test v2! ## Note on code samples diff --git a/doc/getting-started.md b/doc/getting-started.md index 464fdaf..f49781c 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - seancorfield/honeysql {:mvn/version "2.0.0-alpha1"} + seancorfield/honeysql {:mvn/version "2.0.0-alpha2"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [seancorfield/honeysql "2.0.0-alpha1"] + [seancorfield/honeysql "2.0.0-alpha2"] ``` HoneySQL produces SQL statements but does not execute them. @@ -235,7 +235,7 @@ common for people to use the [nilenso/honeysql-postgres library](https://github. to get DDL support, even if they didn't need the PostgreSQL-specific extensions. That library does not work with HoneySQL 2.x but all of the functionality from it has been incorporated -into HoneySQL now and is described in the [PostgreSQL](doc/postgresql.md) +into HoneySQL now and is described in the [PostgreSQL](postgresql.md) section (because that covers all of the things that the nilenso library supported and much of it was PostgreSQL-specific!). @@ -319,6 +319,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha1/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha2/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. diff --git a/pom.xml b/pom.xml index 9114dc8..a268646 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 seancorfield honeysql - 2.0.0-alpha1 + 2.0.0-alpha2 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-alpha1 + v2.0.0-alpha2 From 770beec886a86efe04c08c24ee21e96f2f94d2f3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 22 Feb 2021 10:56:32 -0800 Subject: [PATCH 174/254] Add test for (v1) SQL Injection in insert #299 --- test/honey/sql_test.cljc | 10 ++++++++++ 1 file changed, 10 insertions(+) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3337cd8..0868889 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -584,3 +584,13 @@ ORDER BY id = ? DESC (h/where [:= :state 42]) (h/order-by [[:= :id 123] :desc])) {:pretty true})))) + + +(deftest issue-299-test + (let [name "test field" + ;; this was a bug in v1 -- adding here to prevent regression: + enabled [true, "); SELECT case when (SELECT current_setting('is_superuser'))='off' then pg_sleep(0.2) end; -- "]] + (is (= ["INSERT INTO table (name, enabled) VALUES (?, (TRUE, ?))" name (second enabled)] + (format {:insert-into :table + :values [{:name name + :enabled enabled}]}))))) \ No newline at end of file From 78ca2a05306971c9a4345d913f06ee805fabf4c2 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 27 Feb 2021 09:33:20 -0800 Subject: [PATCH 175/254] Fixes #305 by supporting more complex JOIN source --- src/honey/sql.cljc | 11 +++-- test/honey/sql/helpers_test.cljc | 83 ++++++++++++++++++++++++++++++++ test/honey/sql_test.cljc | 3 +- 3 files changed, 91 insertions(+), 6 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f45d527..6e50bec 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -372,16 +372,19 @@ (defn- format-join [k clauses] (let [[sqls params] (reduce (fn [[sqls params] [j e]] - (let [sqls (conj sqls - (sql-kw (if (= :join k) :inner-join k)) - (format-entity-alias j))] + (let [[sql-j & params-j] + (format-selects-common + (sql-kw (if (= :join k) :inner-join k)) + true + [j]) + sqls (conj sqls sql-j)] (if (and (sequential? e) (= :using (first e))) [(conj sqls "USING" (str "(" (str/join ", " (map #'format-entity-alias (rest e))) ")")) - params] + (into params params-j)] (let [[sql & params'] (when e (format-expr e))] [(cond-> sqls e (conj "ON" sql)) (into params params')])))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 35274e7..320ca19 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -480,3 +480,86 @@ ;; three arguments with an alias and columns: (is (= (sql/format (insert-into '(transport t) '(id, name) '{select (*) from (cars)})) ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"]))) + +;; these tests are adapted from Cam Saul's PR #283 + +(deftest merge-where-no-params-test + (doseq [[k [f merge-f]] {"WHERE" [where where] + "HAVING" [having having]}] + (testing "merge-where called with just the map as parameter - see #228" + (let [sqlmap (-> (select :*) + (from :table) + (f [:= :foo :bar]))] + (is (= [(str "SELECT * FROM table " k " foo = bar")] + (sql/format (apply merge-f sqlmap [])))))))) + +(deftest merge-where-test + (doseq [[k sql-keyword f merge-f] [[:where "WHERE" where where] + [:having "HAVING" having having]]] + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar] [:= :quuz :xyzzy]) + sql/format))) + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar]) + (merge-f [:= :quuz :xyzzy]) + sql/format))) + (testing "Should work when first arg isn't a map" + (is (= {k [:and [:x] [:y]]} + (merge-f [:x] [:y])))) + (testing "Shouldn't use conjunction if there is only one clause in the result" + (is (= {k [:x]} + (merge-f {} [:x])))) + (testing "Should be able to specify the conjunction type" + (is (= {k [:or [:x] [:y]]} + (merge-f {} + :or + [:x] [:y])))) + (testing "Should ignore nil clauses" + (is (= {k [:or [:x] [:y]]} + (merge-f {} + :or + [:x] nil [:y])))))) + +(deftest merge-where-combine-clauses-test + (doseq [[k f] {:where where + :having having}] + (testing (str "Combine new " k " clauses into the existing clause when appropriate. (#282)") + (testing "No existing clause" + (is (= {k [:and [:x] [:y]]} + (f {} + [:x] [:y])))) + (testing "Existing clause is not a conjunction." + (is (= {k [:and [:a] [:x] [:y]]} + (f {k [:a]} + [:x] [:y])))) + (testing "Existing clause IS a conjunction." + (testing "New clause(s) are not conjunctions" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:x] [:y])))) + (testing "New clauses(s) ARE conjunction(s)" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x] [:y]]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:y]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:and [:y]]))))) + (testing "if existing clause isn't the same conjunction, don't merge into it" + (testing "existing conjunction is `:or`" + (is (= {k [:and [:or [:a] [:b]] [:x] [:y]]} + (f {k [:or [:a] [:b]]} + [:x] [:y])))) + (testing "pass conjunction type as a param (override default of :and)" + (is (= {k [:or [:and [:a] [:b]] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + :or + [:x] [:y])))))))) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 0868889..3a475b6 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -585,7 +585,6 @@ ORDER BY id = ? DESC (h/order-by [[:= :id 123] :desc])) {:pretty true})))) - (deftest issue-299-test (let [name "test field" ;; this was a bug in v1 -- adding here to prevent regression: @@ -593,4 +592,4 @@ ORDER BY id = ? DESC (is (= ["INSERT INTO table (name, enabled) VALUES (?, (TRUE, ?))" name (second enabled)] (format {:insert-into :table :values [{:name name - :enabled enabled}]}))))) \ No newline at end of file + :enabled enabled}]}))))) From 5e2036a92259f3de45e24262ff42c383989a56c4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 27 Feb 2021 09:35:03 -0800 Subject: [PATCH 176/254] Temporarily comment out WIP tests --- test/honey/sql/helpers_test.cljc | 152 +++++++++++++++---------------- 1 file changed, 76 insertions(+), 76 deletions(-) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 320ca19..8e5fe6b 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -483,83 +483,83 @@ ;; these tests are adapted from Cam Saul's PR #283 -(deftest merge-where-no-params-test - (doseq [[k [f merge-f]] {"WHERE" [where where] - "HAVING" [having having]}] - (testing "merge-where called with just the map as parameter - see #228" - (let [sqlmap (-> (select :*) - (from :table) - (f [:= :foo :bar]))] - (is (= [(str "SELECT * FROM table " k " foo = bar")] - (sql/format (apply merge-f sqlmap [])))))))) +#_(deftest merge-where-no-params-test + (doseq [[k [f merge-f]] {"WHERE" [where where] + "HAVING" [having having]}] + (testing "merge-where called with just the map as parameter - see #228" + (let [sqlmap (-> (select :*) + (from :table) + (f [:= :foo :bar]))] + (is (= [(str "SELECT * FROM table " k " foo = bar")] + (sql/format (apply merge-f sqlmap [])))))))) -(deftest merge-where-test - (doseq [[k sql-keyword f merge-f] [[:where "WHERE" where where] - [:having "HAVING" having having]]] - (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] - (-> (select :*) - (from :table) - (f [:= :foo :bar] [:= :quuz :xyzzy]) - sql/format))) - (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] - (-> (select :*) - (from :table) - (f [:= :foo :bar]) - (merge-f [:= :quuz :xyzzy]) - sql/format))) - (testing "Should work when first arg isn't a map" - (is (= {k [:and [:x] [:y]]} - (merge-f [:x] [:y])))) - (testing "Shouldn't use conjunction if there is only one clause in the result" - (is (= {k [:x]} - (merge-f {} [:x])))) - (testing "Should be able to specify the conjunction type" - (is (= {k [:or [:x] [:y]]} - (merge-f {} - :or - [:x] [:y])))) - (testing "Should ignore nil clauses" - (is (= {k [:or [:x] [:y]]} - (merge-f {} - :or - [:x] nil [:y])))))) - -(deftest merge-where-combine-clauses-test - (doseq [[k f] {:where where - :having having}] - (testing (str "Combine new " k " clauses into the existing clause when appropriate. (#282)") - (testing "No existing clause" +#_(deftest merge-where-test + (doseq [[k sql-keyword f merge-f] [[:where "WHERE" where where] + [:having "HAVING" having having]]] + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar] [:= :quuz :xyzzy]) + sql/format))) + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar]) + (merge-f [:= :quuz :xyzzy]) + sql/format))) + (testing "Should work when first arg isn't a map" (is (= {k [:and [:x] [:y]]} - (f {} - [:x] [:y])))) - (testing "Existing clause is not a conjunction." - (is (= {k [:and [:a] [:x] [:y]]} - (f {k [:a]} - [:x] [:y])))) - (testing "Existing clause IS a conjunction." - (testing "New clause(s) are not conjunctions" - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} + (merge-f [:x] [:y])))) + (testing "Shouldn't use conjunction if there is only one clause in the result" + (is (= {k [:x]} + (merge-f {} [:x])))) + (testing "Should be able to specify the conjunction type" + (is (= {k [:or [:x] [:y]]} + (merge-f {} + :or + [:x] [:y])))) + (testing "Should ignore nil clauses" + (is (= {k [:or [:x] [:y]]} + (merge-f {} + :or + [:x] nil [:y])))))) + +#_(deftest merge-where-combine-clauses-test + (doseq [[k f] {:where where + :having having}] + (testing (str "Combine new " k " clauses into the existing clause when appropriate. (#282)") + (testing "No existing clause" + (is (= {k [:and [:x] [:y]]} + (f {} [:x] [:y])))) - (testing "New clauses(s) ARE conjunction(s)" - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x] [:y]]))) - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x]] - [:y]))) - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x]] - [:and [:y]]))))) - (testing "if existing clause isn't the same conjunction, don't merge into it" - (testing "existing conjunction is `:or`" - (is (= {k [:and [:or [:a] [:b]] [:x] [:y]]} - (f {k [:or [:a] [:b]]} + (testing "Existing clause is not a conjunction." + (is (= {k [:and [:a] [:x] [:y]]} + (f {k [:a]} [:x] [:y])))) - (testing "pass conjunction type as a param (override default of :and)" - (is (= {k [:or [:and [:a] [:b]] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - :or - [:x] [:y])))))))) + (testing "Existing clause IS a conjunction." + (testing "New clause(s) are not conjunctions" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:x] [:y])))) + (testing "New clauses(s) ARE conjunction(s)" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x] [:y]]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:y]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:and [:y]]))))) + (testing "if existing clause isn't the same conjunction, don't merge into it" + (testing "existing conjunction is `:or`" + (is (= {k [:and [:or [:a] [:b]] [:x] [:y]]} + (f {k [:or [:a] [:b]]} + [:x] [:y])))) + (testing "pass conjunction type as a param (override default of :and)" + (is (= {k [:or [:and [:a] [:b]] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + :or + [:x] [:y])))))))) From 06d90c174e988f9118427f814168431f04656ab5 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Mar 2021 18:40:23 -0800 Subject: [PATCH 177/254] Rework and-merge WIP (tests fail) --- src/honey/sql/helpers.cljc | 43 ++++++--- test/honey/sql/helpers_test.cljc | 160 ++++++++++++++++--------------- 2 files changed, 113 insertions(+), 90 deletions(-) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index bae9616..b9ba8e8 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -11,20 +11,39 @@ (into (vec current) args)) (defn- and-merge + "Recursively merge args into the current expression." [current args] (let [args (remove nil? args)] - (cond (= :and (first current)) - (default-merge current args) - (seq current) - (if (seq args) - (default-merge [:and current] args) - current) - (= 1 (count args)) - (vec (first args)) - (seq args) - (default-merge [:and] args) - :else - (vec current)))) + (cond (= :and (first args)) + (recur current [args]) + (= :or (first args)) + (recur [:or current] (rest args)) + :else + (let [arg (first args) + conj-1 (#{:and :or} (first current)) + conj-2 (#{:and :or} (and (sequential? arg) (first arg)))] + (cond (empty? args) + ;; nothing more to merge: + (vec current) + (and conj-1 conj-2 (= conj-1 conj-2)) + ;; both conjunctions and they match: + (recur (default-merge current (rest arg)) (rest args)) + (and conj-1 conj-2) + ;; both conjunctions but they don't match: + (if (= :and conj-1) + (recur (default-merge current [arg]) (rest args)) + (recur (default-merge [:and current] (rest arg)) (rest args))) + conj-1 + ;; current is conjunction; arg is not + (recur (default-merge (if (= :and conj-1) current [:and current]) [arg]) (rest args)) + (and conj-2 (seq current)) + ;; arg is conjunction; current is not + (recur (default-merge [conj-2 current] (rest arg)) (rest args)) + (seq current) + ;; current non-empty; neither is a conjunction + (recur (default-merge [:and current] [arg]) (rest args)) + :else ; current is empty; use arg as current + (recur (if (sequential? arg) arg [arg]) (rest args))))))) (def ^:private special-merges {:where #'and-merge diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 8e5fe6b..a01e9a1 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -483,83 +483,87 @@ ;; these tests are adapted from Cam Saul's PR #283 -#_(deftest merge-where-no-params-test - (doseq [[k [f merge-f]] {"WHERE" [where where] - "HAVING" [having having]}] - (testing "merge-where called with just the map as parameter - see #228" - (let [sqlmap (-> (select :*) - (from :table) - (f [:= :foo :bar]))] - (is (= [(str "SELECT * FROM table " k " foo = bar")] - (sql/format (apply merge-f sqlmap [])))))))) +(deftest merge-where-no-params-test + (doseq [[k [f merge-f]] {"WHERE" [where where] + "HAVING" [having having]}] + (testing "merge-where called with just the map as parameter - see #228" + (let [sqlmap (-> (select :*) + (from :table) + (f [:= :foo :bar]))] + (is (= [(str "SELECT * FROM table " k " foo = bar")] + (sql/format (apply merge-f sqlmap [])))))))) -#_(deftest merge-where-test - (doseq [[k sql-keyword f merge-f] [[:where "WHERE" where where] - [:having "HAVING" having having]]] - (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] - (-> (select :*) - (from :table) - (f [:= :foo :bar] [:= :quuz :xyzzy]) - sql/format))) - (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] - (-> (select :*) - (from :table) - (f [:= :foo :bar]) - (merge-f [:= :quuz :xyzzy]) - sql/format))) - (testing "Should work when first arg isn't a map" - (is (= {k [:and [:x] [:y]]} - (merge-f [:x] [:y])))) - (testing "Shouldn't use conjunction if there is only one clause in the result" - (is (= {k [:x]} - (merge-f {} [:x])))) - (testing "Should be able to specify the conjunction type" - (is (= {k [:or [:x] [:y]]} - (merge-f {} - :or - [:x] [:y])))) - (testing "Should ignore nil clauses" - (is (= {k [:or [:x] [:y]]} - (merge-f {} - :or - [:x] nil [:y])))))) - -#_(deftest merge-where-combine-clauses-test - (doseq [[k f] {:where where - :having having}] - (testing (str "Combine new " k " clauses into the existing clause when appropriate. (#282)") - (testing "No existing clause" - (is (= {k [:and [:x] [:y]]} - (f {} - [:x] [:y])))) - (testing "Existing clause is not a conjunction." - (is (= {k [:and [:a] [:x] [:y]]} - (f {k [:a]} - [:x] [:y])))) - (testing "Existing clause IS a conjunction." - (testing "New clause(s) are not conjunctions" - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:x] [:y])))) - (testing "New clauses(s) ARE conjunction(s)" - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x] [:y]]))) - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x]] - [:y]))) - (is (= {k [:and [:a] [:b] [:x] [:y]]} - (f {k [:and [:a] [:b]]} - [:and [:x]] - [:and [:y]]))))) - (testing "if existing clause isn't the same conjunction, don't merge into it" - (testing "existing conjunction is `:or`" - (is (= {k [:and [:or [:a] [:b]] [:x] [:y]]} - (f {k [:or [:a] [:b]]} - [:x] [:y])))) - (testing "pass conjunction type as a param (override default of :and)" - (is (= {k [:or [:and [:a] [:b]] [:x] [:y]]} - (f {k [:and [:a] [:b]]} +(deftest merge-where-test + (doseq [[k sql-keyword f merge-f] [[:where "WHERE" where where] + [:having "HAVING" having having]]] + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar] [:= :quuz :xyzzy]) + sql/format))) + (is (= [(str "SELECT * FROM table " sql-keyword " (foo = bar) AND (quuz = xyzzy)")] + (-> (select :*) + (from :table) + (f [:= :foo :bar]) + (merge-f [:= :quuz :xyzzy]) + sql/format))) + (testing "Should work when first arg isn't a map" + (is (= {k [:and [:x] [:y]]} + (merge-f [:x] [:y])))) + (testing "Shouldn't use conjunction if there is only one clause in the result" + (is (= {k [:x]} + (merge-f {} [:x])))) + (testing "Should be able to specify the conjunction type" + (is (= {k [:or [:x] [:y]]} + (merge-f {} :or - [:x] [:y])))))))) + [:x] [:y])))) + (testing "Should ignore nil clauses" + (is (= {k [:or [:x] [:y]]} + (merge-f {} + :or + [:x] nil [:y])))))) + +(deftest merge-where-combine-clauses-test + (doseq [[k f] {:where where + :having having}] + (testing (str "Combine new " k " clauses into the existing clause when appropriate. (#282)") + (testing "No existing clause" + (is (= {k [:and [:x] [:y]]} + (f {} + [:x] [:y])))) + (testing "Existing clause is not a conjunction." + (is (= {k [:and [:a] [:x] [:y]]} + (f {k [:a]} + [:x] [:y])))) + (testing "Existing clause IS a conjunction." + (testing "New clause(s) are not conjunctions" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:x] [:y])))) + (testing "New clauses(s) ARE conjunction(s)" + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x] [:y]]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:y]))) + (is (= {k [:and [:a] [:b] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + [:and [:x]] + [:and [:y]]))))) + (testing "if existing clause isn't the same conjunction, don't merge into it" + (testing "existing conjunction is `:or`" + (is (= {k [:and [:or [:a] [:b]] [:x] [:y]]} + (f {k [:or [:a] [:b]]} + [:x] [:y])))) + (testing "pass conjunction type as a param (override default of :and)" + (is (= {k [:or [:and [:a] [:b]] [:x] [:y]]} + (f {k [:and [:a] [:b]]} + :or + [:x] [:y])))))))) + +(comment + (where {:where [:and [:a] [:b]]} [:and [:x] [:y]]) + .) From b600348808a791c91eba7fc9483c49aacd26595f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Mar 2021 22:10:43 -0800 Subject: [PATCH 178/254] Addresses #283 on the v1 branch --- CHANGELOG.md | 3 ++ src/honey/sql/helpers.cljc | 75 +++++++++++++++++--------------- test/honey/sql/helpers_test.cljc | 4 -- 3 files changed, 42 insertions(+), 40 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 26876b6..42620b3 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.0-alpha3 in progress + * Reconcile `where` behavior with recent 1.0 changes. + * 2.0.0-alpha2 (for early testing) * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. * Numerous small improvements have been made to clauses and helpers around insert/upsert. diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index b9ba8e8..c490519 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -11,47 +11,50 @@ (into (vec current) args)) (defn- and-merge - "Recursively merge args into the current expression." + [current arg] + (if-let [conj' (and (sequential? arg) (#{:and :or} (first arg)))] + (cond (= conj' (first current)) + (into (vec current) (rest arg)) + (seq current) + (into [conj' current] (rest arg)) + :else + (into [conj'] (rest arg))) + (cond (= :and (first current)) + (conj (vec current) arg) + (seq current) + (conj [:and current] arg) + :else + (conj [:and] arg)))) + +(defn- and-merges [current args] - (let [args (remove nil? args)] - (cond (= :and (first args)) - (recur current [args]) - (= :or (first args)) - (recur [:or current] (rest args)) - :else - (let [arg (first args) - conj-1 (#{:and :or} (first current)) - conj-2 (#{:and :or} (and (sequential? arg) (first arg)))] - (cond (empty? args) - ;; nothing more to merge: - (vec current) - (and conj-1 conj-2 (= conj-1 conj-2)) - ;; both conjunctions and they match: - (recur (default-merge current (rest arg)) (rest args)) - (and conj-1 conj-2) - ;; both conjunctions but they don't match: - (if (= :and conj-1) - (recur (default-merge current [arg]) (rest args)) - (recur (default-merge [:and current] (rest arg)) (rest args))) - conj-1 - ;; current is conjunction; arg is not - (recur (default-merge (if (= :and conj-1) current [:and current]) [arg]) (rest args)) - (and conj-2 (seq current)) - ;; arg is conjunction; current is not - (recur (default-merge [conj-2 current] (rest arg)) (rest args)) - (seq current) - ;; current non-empty; neither is a conjunction - (recur (default-merge [:and current] [arg]) (rest args)) - :else ; current is empty; use arg as current - (recur (if (sequential? arg) arg [arg]) (rest args))))))) + (let [args (remove nil? args) + result + (cond (keyword? (first args)) + (and-merges current [args]) + (seq args) + (let [[arg & args] args] + (and-merges (and-merge current arg) args)) + :else + current)] + (case (count result) + 0 nil + 1 (if (sequential? (first result))(first result) result) + 2 (if (#{:and :or} (first result)) + (second result) + result) + result))) (def ^:private special-merges - {:where #'and-merge - :having #'and-merge}) + {:where #'and-merges + :having #'and-merges}) (defn- helper-merge [data k args] - (let [merge-fn (special-merges k default-merge)] - (clojure.core/update data k merge-fn args))) + (if-let [merge-fn (special-merges k)] + (if-let [clause (merge-fn (get data k) args)] + (assoc data k clause) + data) + (clojure.core/update data k default-merge args))) (defn- generic [k args] (if (map? (first args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index a01e9a1..320ca19 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -563,7 +563,3 @@ (f {k [:and [:a] [:b]]} :or [:x] [:y])))))))) - -(comment - (where {:where [:and [:a] [:b]]} [:and [:x] [:y]]) - .) From 1bbdfeef7550c5359459e36c7a016edbbb7e8320 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Mar 2021 22:19:02 -0800 Subject: [PATCH 179/254] Update changelog to reflect current state --- CHANGELOG.md | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 42620b3..1773384 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,7 +1,9 @@ # Changes * 2.0.0-alpha3 in progress - * Reconcile `where` behavior with recent 1.0 changes. + * Fix #305 by supporting more complex join clauses. + * Add tests to confirm #299 does not affect v2. + * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * 2.0.0-alpha2 (for early testing) * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. From 77577517c89d864885ea40f0cd16763f34c8b5b0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Mar 2021 22:27:53 -0800 Subject: [PATCH 180/254] Note parity with nilenso/honeysql-postgres --- CHANGELOG.md | 1 + 1 file changed, 1 insertion(+) diff --git a/CHANGELOG.md b/CHANGELOG.md index 1773384..a35cd59 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -3,6 +3,7 @@ * 2.0.0-alpha3 in progress * Fix #305 by supporting more complex join clauses. * Add tests to confirm #299 does not affect v2. + * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * 2.0.0-alpha2 (for early testing) From 41522c89a1a32de21804731eed575118e07d4fa4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Mar 2021 09:43:03 -0800 Subject: [PATCH 181/254] Clarify 1.9+ Clojure support --- README.md | 6 ++++-- deps.edn | 4 ++-- doc/differences-from-1-x.md | 2 ++ src/honey/sql.cljc | 38 +++++++++++++++++-------------------- src/honey/sql/helpers.cljc | 8 +++++--- 5 files changed, 30 insertions(+), 28 deletions(-) diff --git a/README.md b/README.md index c982b6b..ef11aae 100644 --- a/README.md +++ b/README.md @@ -10,10 +10,12 @@ The latest stable version (1.0.444) on Clojars and on cljdoc (note: `honeysql/ho This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. -Prerelease builds of the upcoming 2.x version of HoneySQL will soon be available: +Prerelease builds of the upcoming 2.x version of HoneySQL are available for testing: [![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha2)](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha2) +HoneySQL 2.x requires Clojure 1.9 or later. + This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). See this [summary of differences between v1 and v2](doc/differences-from-1-x.md) if you want to help test v2! @@ -631,7 +633,7 @@ You can also register SQL clauses, specifying the keyword, the formatting functi (sql/register-clause! :foobar (fn [clause x] (let [[sql & params] - (if (keyword? x) + (if (ident? x) (sql/format-expr x) (sql/format-dsl x))] (into [(str (sql/sql-kw clause) " " sql)] params))) diff --git a/deps.edn b/deps.edn index f511376..35a4240 100644 --- a/deps.edn +++ b/deps.edn @@ -1,9 +1,9 @@ {:mvn/repos {"sonatype" {:url "https://oss.sonatype.org/content/repositories/snapshots/"}} :paths ["src"] - :deps {org.clojure/clojure {:mvn/version "1.10.2"}} + :deps {org.clojure/clojure {:mvn/version "1.9.0"}} :aliases {:1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} - :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.2"}}} + :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.3"}}} :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.0-master-SNAPSHOT"}}} :test {:extra-paths ["test"]} :runner diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 1103da9..5e5aef2 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -6,6 +6,8 @@ The goal of HoneySQL 2.x is to provide an easily-extensible DSL for SQL, support The DSL itself -- the data structures that both versions convert to SQL and parameters via the `format` function -- is almost exactly the same between the two versions so that migration is relatively painless. The primary API -- the `format` function -- is preserved in 2.x, although the variadic options from 1.x have changed to an options hash map in 2.x as this is generally considered more idiomatic. See the **Option Changes** section below for the differences in the options supported. +HoneySQL 1.x supported Clojure 1.7 and later. HoneySQL 2.x requires Clojure 1.9 or later. + ## Group, Artifact, and Namespaces HoneySQL 2.x uses the group ID `seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 6e50bec..dba295f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -133,16 +133,6 @@ (keyword (name s))) s)) -(defn- kw->sym - "Given a keyword, produce a symbol, retaining the namespace - qualifier, if any." - [k] - (if (keyword? k) - (if-let [n (namespace k)] - (symbol n (name k)) - (symbol (name k))) - k)) - (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) @@ -150,8 +140,7 @@ (cond (nil? x) "NULL" (string? x) (str \' (str/replace x "'" "''") \') - (symbol? x) (sql-kw x) - (keyword? x) (sql-kw x) + (ident? x) (sql-kw x) :else (str x))) (defn format-entity @@ -242,7 +231,7 @@ (into params) (into params'))) - (or (keyword? x) (symbol? x)) + (ident? x) (if aliased [(format-entity x opts)] (format-var x opts)) @@ -417,11 +406,8 @@ [(str (sql-kw k) " " (sql-kw strength) (when tables (str - (cond (and (keyword? tables) - (#{:nowait :skip-locked :wait} tables)) - (str " " (sql-kw tables)) - (and (symbol? tables) - ('#{nowait skip-locked wait} tables)) + (cond (and (ident? tables) + (#{:nowait :skip-locked :wait} (sym->kw tables))) (str " " (sql-kw tables)) (sequential? tables) (str " OF " @@ -493,13 +479,13 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-on-conflict [k x] - (cond (or (keyword? x) (symbol? x)) + (cond (ident? x) [(str (sql-kw k) " (" (format-entity x) ")")] (map? x) (let [[sql & params] (format-dsl x)] (into [(str (sql-kw k) " " sql)] params)) (and (sequential? x) - (or (keyword? (first x)) (symbol? (first x))) + (ident? (first x)) (map? (second x))) (let [[sql & params] (format-dsl (second x))] (into [(str (sql-kw k) @@ -669,6 +655,16 @@ (set @current-clause-order) (set (keys @clause-format)))) +(defn- kw->sym + "Given a keyword, produce a symbol, retaining the namespace + qualifier, if any." + [k] + (if (keyword? k) + (if-let [n (namespace k)] + (symbol n (name k)) + (symbol (name k))) + k)) + (defn format-dsl "Given a hash map representing a SQL statement and a hash map of options, return a vector containing a string -- the formatted @@ -891,7 +887,7 @@ This is intended to be used when writing your own formatters to extend the DSL supported by HoneySQL." [expr & [{:keys [nested] :as opts}]] - (cond (or (keyword? expr) (symbol? expr)) + (cond (ident? expr) (format-var expr opts) (map? expr) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index c490519..6de99c7 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -12,14 +12,16 @@ (defn- and-merge [current arg] - (if-let [conj' (and (sequential? arg) (#{:and :or} (first arg)))] + (if-let [conj' (and (sequential? arg) + (ident? (first arg)) + (#{:and :or} (keyword (first arg))))] (cond (= conj' (first current)) (into (vec current) (rest arg)) (seq current) (into [conj' current] (rest arg)) :else (into [conj'] (rest arg))) - (cond (= :and (first current)) + (cond (#{:and 'and} (first current)) (conj (vec current) arg) (seq current) (conj [:and current] arg) @@ -30,7 +32,7 @@ [current args] (let [args (remove nil? args) result - (cond (keyword? (first args)) + (cond (ident? (first args)) (and-merges current [args]) (seq args) (let [[arg & args] args] From d789c00f5433e686301a744b588b597f53f2515d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Mar 2021 09:45:08 -0800 Subject: [PATCH 182/254] Reflect latest 1.x version --- CHANGELOG.md | 4 ++++ README.md | 4 ++-- doc/differences-from-1-x.md | 4 ++-- 3 files changed, 8 insertions(+), 4 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index a35cd59..9db4e4f 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -17,6 +17,10 @@ # HoneySQL pre-2.x Changes +* 1.0.461 -- 2021-02-22 + * **Fix #299 potential SQL injection vulnerability.** + * Fix/Improve `merge-where` (and `merge-having`) behavior. #282 via #283 (@camsaul) + * 1.0.444 -- 2020-05-29 * Fix #259 so column names are always unqualified in inserts. (@jrdoane) * Fix #257 by adding support for `cross-join` / `merge-cross-join` / `:cross-join`. (@dcj) diff --git a/README.md b/README.md index ef11aae..a3158fb 100644 --- a/README.md +++ b/README.md @@ -4,9 +4,9 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -The latest stable version (1.0.444) on Clojars and on cljdoc (note: `honeysql/honeysql`): +The latest stable version (1.0.461) on Clojars and on cljdoc (note: `honeysql/honeysql`): -[![Clojars Project](https://clojars.org/honeysql/honeysql/latest-version.svg)](https://clojars.org/honeysql/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.444)](https://cljdoc.org/d/honeysql/honeysql/CURRENT) +[![Clojars Project](https://clojars.org/honeysql/honeysql/latest-version.svg)](https://clojars.org/honeysql/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.461)](https://cljdoc.org/d/honeysql/honeysql/1.0.461) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 5e5aef2..3277b6d 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -18,9 +18,9 @@ In addition, HoneySQL 2.x contains different namespaces so you can have both ver ```clojure ;; in deps.edn: -honeysql {:mvn/version "1.0.444"} +honeysql {:mvn/version "1.0.461"} ;; or, more correctly: -honeysql/honeysql {:mvn/version "1.0.444"} +honeysql/honeysql {:mvn/version "1.0.461"} ;; in use: (ns my.project From 97c92368423960f1e5d1b729c97d88f21aff6a30 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Mar 2021 17:07:38 -0800 Subject: [PATCH 183/254] Fixes #307 by adding data DSL examples I've added a pure data DSL version of nearly all the helper function examples. I've added a few examples of the data DSL with symbols instead of keywords as well. --- README.md | 123 +++++++++++++++++++++++++++++++++++++++++++++++++++++- 1 file changed, 121 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index a3158fb..65d1a95 100644 --- a/README.md +++ b/README.md @@ -53,6 +53,10 @@ Column names can be provided as keywords or symbols (but not strings -- HoneySQL ```clojure (sql/format sqlmap) => ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] +;; sqlmap as symbols instead of keywords: +(-> '{select (a, b, c) from (foo) where (= f.a "baz")} + (sql/format)) +=> ["SELECT a, b, c FROM foo WHERE f.a = ?" "baz"] ``` HoneySQL is a relatively "pure" library, it does not manage your sql connection @@ -82,16 +86,25 @@ _[In HoneySQL 1.x, this was the behavior when `:namespace-as-table? true` was sp :where [:= :foo/a "baz"]}) (sql/format q-sqlmap) => ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] +;; this also works with symbols instead of keywords: +(-> '{select (foo/a, foo/b, foo/c) + from (foo) + where (= foo/a "baz")} + (sql/format)) +=> ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] ``` ### Vanilla SQL clause helpers -There are also functions for each clause type in the `honey.sql.helpers` namespace: +For every single SQL clause supported by HoneySQL (as keywords or symbols +in the data structure that is the DSL), there is also a corresponding +function in the `honey.sql.helpers` namespace: ```clojure (-> (select :a :b :c) (from :foo) (where [:= :f.a "baz"])) +=> {:select [:a :b :c] :from [:foo] :where [:= :f.a "baz"]} ``` Order doesn't matter (for independent clauses): @@ -145,6 +158,11 @@ In particular, note that `(select [:a :b])` means `SELECT a AS b` rather than `SELECT a, b` -- helpers like `select` are generally variadic and do not take a collection of column names. +The examples in this README use a mixture of data structures and the helper +functions interchangably. For any example using the helpers, you could evaluate +it (without the call to `sql/format`) to see what the equivalent data structure +would be. + ### Inserts Inserts are supported in two patterns. @@ -165,6 +183,19 @@ INSERT INTO properties VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) " "Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] +;; or as pure data DSL: +(-> {:insert-into [:properties] + :columns [:name :surname :age] + :values [["Jon" "Smith" 34] + ["Andrew" "Cooper" 12] + ["Jane" "Daniels" 56]]} + (sql/format {:pretty true})) +=> [" +INSERT INTO properties +(name, surname, age) +VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] ``` If the rows are of unequal lengths, they will be padded with `NULL` values to make them consistent. @@ -184,6 +215,19 @@ INSERT INTO properties "John" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56] +;; or as pure data DSL: +(-> {:insert-into [:properties] + :values [{:name "John", :surname "Smith", :age 34} + {:name "Andrew", :surname "Cooper", :age 12} + {:name "Jane", :surname "Daniels", :age 56}]} + (sql/format {:pretty true})) +=> [" +INSERT INTO properties +(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?) +" +"John" "Smith" 34 +"Andrew" "Cooper" 12 +"Jane" "Daniels" 56] ``` The set of columns used in the insert will be the union of all column names from all @@ -209,13 +253,34 @@ INSERT INTO user_profile_to_role " 12345 "user"] +;; or as pure data DSL: +(let [user-id 12345 + role-name "user"] + (-> {:insert-into [:user_profile_to_role] + :values [{:user_profile_id 12345, + :role_id {:select [:id], + :from [:role], + :where [:= :name "user"]}}]} + (sql/format {:pretty true}))) +=> [" +INSERT INTO user_profile_to_role +(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?)) +" +12345 +"user"] ``` ```clojure (-> (select :*) (from :foo) (where [:in :foo.a (-> (select :a) (from :bar))]) - sql/format) + (sql/format)) +=> ["SELECT * FROM foo WHERE foo.a IN (SELECT a FROM bar)"] +;; or as pure data DSL: +(-> {:select [:*], + :from [:foo], + :where [:in :foo.a {:select [:a], :from [:bar]}]} + (sql/format)) => ["SELECT * FROM foo WHERE foo.a IN (SELECT a FROM bar)"] ``` @@ -236,6 +301,18 @@ INSERT INTO comp_table VALUES (?, (?, ?)), (?, (?, ?)) " "small" 1 "inch" "large" 10 "feet"] +;; or as pure data DSL: +(-> {:insert-into [:comp_table], + :columns [:name :comp_column], + :values [["small" [:composite 1 "inch"]] + ["large" [:composite 10 "feet"]]]} + (sql/format {:pretty true})) +=> [" +INSERT INTO comp_table +(name, comp_column) +VALUES (?, (?, ?)), (?, (?, ?)) +" +"small" 1 "inch" "large" 10 "feet"] ``` ### Updates @@ -256,6 +333,19 @@ WHERE kind = ? "dramatic" 1 "drama"] +;; or as pure data DSL: +(-> {:update :films, + :set {:kind "dramatic", :watched [:+ :watched 1]}, + :where [:= :kind "drama"]} + (sql/format {:pretty true})) +=> [" +UPDATE films +SET kind = ?, watched = watched + ? +WHERE kind = ? +" +"dramatic" +1 +"drama"] ``` If you are trying to build a compound update statement (with `from` or `join`), @@ -274,6 +364,11 @@ Deletes look as you would expect: (where [:<> :kind "musical"]) (sql/format)) => ["DELETE FROM films WHERE kind <> ?" "musical"] +;; or as pure data DSL: +(-> {:delete-from [:films], + :where [:<> :kind "musical"]} + (sql/format)) +=> ["DELETE FROM films WHERE kind <> ?" "musical"] ``` If your database supports it, you can also delete from multiple tables: @@ -291,6 +386,19 @@ INNER JOIN directors ON films.director_id = directors.id WHERE kind <> ? " "musical"] +;; or pure data DSL: +(-> {:delete [:films :directors], + :from [:films], + :join [:directors [:= :films.director_id :directors.id]], + :where [:<> :kind "musical"]} + (sql/format {:pretty true})) +=> [" +DELETE films, directors +FROM films +INNER JOIN directors ON films.director_id = directors.id +WHERE kind <> ? +" +"musical"] ``` If you want to delete everything from a table, you can use `truncate`: @@ -299,6 +407,10 @@ If you want to delete everything from a table, you can use `truncate`: (-> (truncate :films) (sql/format)) => ["TRUNCATE films"] +;; or as pure data DSL: +(-> {:truncate :films} + (sql/format)) +=> ["TRUNCATE films"] ``` ### Set operations @@ -344,6 +456,9 @@ regular function calls in a select: ```clojure (-> (select [[:max :id]]) (from :foo) sql/format) => ["SELECT MAX(id) FROM foo"] +;; the pure data DSL requires an extra level of brackets: +(-> {:select [[[:max :id]]], :from [:foo]} sql/format) +=> ["SELECT MAX(id) FROM foo"] ``` ### Bindable parameters @@ -356,6 +471,10 @@ Keywords that begin with `?` are interpreted as bindable parameters: (where [:= :a :?baz]) (sql/format {:params {:baz "BAZ"}})) => ["SELECT id FROM foo WHERE a = ?" "BAZ"] +;; or as pure data DSL: +(-> {:select [:id], :from [:foo], :where [:= :a :?baz]} + (sql/format {:params {:baz "BAZ"}})) +=> ["SELECT id FROM foo WHERE a = ?" "BAZ"] ``` ### Miscellaneous From e70985e93beab6ed719b30f7d981d2bf5d0301b4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Mar 2021 19:21:13 -0800 Subject: [PATCH 184/254] Fixes #277 by adding join-by --- CHANGELOG.md | 1 + doc/clause-reference.md | 24 ++++++++++++++++++++ src/honey/sql.cljc | 38 ++++++++++++++++++++++++++++++++ src/honey/sql/helpers.cljc | 16 ++++++++++++++ test/honey/sql/helpers_test.cljc | 26 +++++++++++++++++++++- 5 files changed, 104 insertions(+), 1 deletion(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 9db4e4f..b294c8e 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -5,6 +5,7 @@ * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). + * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. * 2.0.0-alpha2 (for early testing) * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 09aaca6..9e52a52 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -410,6 +410,8 @@ user=> (sql/format {:select [:u.username :s.name] ["SELECT u.username, s.name FROM user AS u INNER JOIN status AS s ON u.statusid = s.id WHERE s.id = ?" 2] ``` +`:join` is shorthand for `:inner-join`. + An alternative to a join condition is a `USING` expression: ```clojure @@ -430,6 +432,28 @@ table name and an alias. > Note: the actual formatting of a `:cross-join` clause is currently identical to the formatting of a `:select` clause. +## join-by + +This is a convenience that allows for an arbitrary sequence of `JOIN` +operations to be performed in a specific order. It accepts a sequence +of join operation name (keyword or symbol) and the clause that join +would take: + +```clojure +user=> (sql/format {:select [:t.ref :pp.code] + :from [[:transaction :t]] + :join-by [:left [[:paypal-tx :pp] + [:using :id]] + :join [[:logtransaction :log] + [:= :t.id :log.id]]] + :where [:= "settled" :pp.status]}) +["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id WHERE ? = pp.status" "settled"] +``` + +Without `:join-by`, a `:join` would normally be generated before a `:left-join`. +To avoid repetition, `:join-by` allows shorthand versions of the join clauses +using a keyword (or symbol) without the `-join` suffix, as shown in this example. + ## set (MySQL) This is the precedence of the `:set` clause for the MySQL dialect. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index dba295f..0fe7e47 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -46,6 +46,7 @@ :select :select-distinct :select-distinct-on :insert-into :update :delete :delete-from :truncate :columns :set :from :using + :join-by :join :left-join :right-join :inner-join :outer-join :full-join :cross-join :where :group-by :having @@ -381,6 +382,42 @@ (partition 2 clauses))] (into [(str/join " " sqls)] params))) +(def ^:private join-by-aliases + "Map of shorthand to longhand join names." + {:join :inner-join + :left :left-join + :right :right-join + :inner :inner-join + :outer :outer-join + :full :full-join + :cross :cross-join}) + +(def ^:private valid-joins + (set (vals join-by-aliases))) + +(defn- format-join-by + "Clauses should be a sequence of join types followed + by their table and condition, so that you can construct + a series of joins in a specific order." + [_ clauses] + (let [joins (partition-by ident? clauses)] + (when-not (even? (count joins)) + (throw (ex-info ":join-by expects a sequence of join clauses" + {:clauses clauses}))) + (let [[sqls params] + (reduce (fn [[sqls params] [[j] [clauses]]] + (let [j' (sym->kw j) + j' (sym->kw (join-by-aliases j' j'))] + (when-not (valid-joins j') + (throw (ex-info (str ":join-by found an invalid join type " + j) + {}))) + (let [[sql' & params'] (format-dsl {j' clauses})] + [(conj sqls sql') (into params params')]))) + [[] []] + (partition 2 joins))] + (into [(str/join " " sqls)] params)))) + (defn- format-on-expr [k e] (if (or (not (sequential? e)) (seq e)) (let [[sql & params] (format-expr e)] @@ -628,6 +665,7 @@ :set #'format-set-exprs :from #'format-selects :using #'format-selects + :join-by #'format-join-by :join #'format-join :left-join #'format-join :right-join #'format-join diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 6de99c7..0177e50 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -393,6 +393,22 @@ [& args] (generic :using args)) +(defn join-by + "Accepts a sequence of join clauses to be generated + in a specific order. + + (-> (select :*) + (from :foo) + (join-by :left :bar [:= :foo.id :bar.id] + :join :quux [:= :bar.qid = :quux.id]) + + This produces a LEFT JOIN followed by an INNER JOIN + even though the 'natural' order for `left-join` and + `join` would be to generate the INNER JOIN first, + followed by the LEFT JOIN." + [& args] + (generic :join-by args)) + (defn join [& args] (generic :join args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 320ca19..c59638f 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -9,7 +9,7 @@ :refer [add-column add-index alter-table columns create-table create-view cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into - join left-join limit offset on-conflict order-by + join-by join left-join limit offset on-conflict order-by over partition-by rename-column rename-table returning right-join select select-distinct values where window with with-columns]])) @@ -75,6 +75,30 @@ ;; to enable :lock :dialect :mysql :quoted false})))))) +(deftest join-by-test + (testing "Natural JOIN orders" + (is (= ["SELECT * FROM foo INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y"] + (sql/format {:select [:*] :from [:foo] + :full-join [:beck [:= :beck.x :c.y]] + :right-join [:bock [:= :bock.z :c.e]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :join [:draq [:= :f.b :draq.x]]})))) + (testing "Specific JOIN orders" + (is (= ["SELECT * FROM foo FULL JOIN beck ON beck.x = c.y RIGHT JOIN bock ON bock.z = c.e LEFT JOIN clod AS c ON f.a = c.d INNER JOIN draq ON f.b = draq.x"] + (sql/format {:select [:*] :from [:foo] + :join-by [:full [:beck [:= :beck.x :c.y]] + :right [:bock [:= :bock.z :c.e]] + :left [[:clod :c] [:= :f.a :c.d]] + :join [:draq [:= :f.b :draq.x]]]}))) + (is (= ["SELECT * FROM foo FULL JOIN beck ON beck.x = c.y RIGHT JOIN bock ON bock.z = c.e LEFT JOIN clod AS c ON f.a = c.d INNER JOIN draq ON f.b = draq.x"] + (-> (select :*) + (from :foo) + (join-by :full-join [:beck [:= :beck.x :c.y]] + :right-join [:bock [:= :bock.z :c.e]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :inner-join [:draq [:= :f.b :draq.x]]) + (sql/format)))))) + (deftest test-cast (is (= ["SELECT foo, CAST(bar AS integer)"] (sql/format {:select [:foo [[:cast :bar :integer]]]}))) From efcee05e0a5f751fb6f6c2e0ece8b77b98bb235d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 7 Mar 2021 22:13:25 -0800 Subject: [PATCH 185/254] Beginnings of generic create #301 #306 --- src/honey/sql.cljc | 35 +++++++++++++++++++++++++---------- 1 file changed, 25 insertions(+), 10 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0fe7e47..152999d 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -575,14 +575,29 @@ (str " " (str/join ", " (map #'format-simple-clause clauses)))))] [(str (sql-kw k) " " (format-entity x))])) -(defn- format-create-table [k table] - (let [[table if-not-exists] (if (sequential? table) table [table])] - [(str (sql-kw k) " " - (when if-not-exists (str (sql-kw :if-not-exists) " ")) - (format-entity table))])) +(defn- destructure-create-item [table] + (let [coll + (if (sequential? table) + table + [table]) + ine (last coll) + [prequel table ine] + (if (= :if-not-exists (sym->kw ine)) + [(butlast (butlast coll)) (last (butlast coll)) ine] + [(butlast coll) (last coll) nil])] + [(str/join " " (map sql-kw prequel)) + (format-entity table) + (when ine (sql-kw ine))])) -(defn- format-create-view [k x] - [(str (sql-kw k) " " (format-entity x) " AS")]) +(defn- format-create [k item as] + (let [[pre i ine] (destructure-create-item item)] + [(str/join " " (remove nil? + [(sql-kw :create) + (when (seq pre) pre) + (sql-kw k) + ine + i + (when as (sql-kw as))]))])) (defn- format-drop-table [k params] @@ -639,10 +654,10 @@ :add-index (fn [_ x] (format-on-expr :add x)) :drop-index #'format-selector :rename-table (fn [_ x] (format-selector :rename-to x)) - :create-table #'format-create-table - :create-extension #'format-create-table + :create-table (fn [_ x] (format-create :table x nil)) + :create-extension (fn [_ x] (format-create :extension x nil)) :with-columns #'format-table-columns - :create-view #'format-create-view + :create-view (fn [_ x] (format-create :view x :as)) :drop-table #'format-drop-table :drop-extension #'format-drop-table :nest (fn [_ x] (format-expr x)) From 445fb08e2fcd84862a01d147876b00ac2c96846f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 11 Mar 2021 20:07:59 -0800 Subject: [PATCH 186/254] Initial work to support #301 --- doc/clause-reference.md | 4 ++++ src/honey/sql.cljc | 15 ++++++++++++--- src/honey/sql/helpers.cljc | 26 ++++++++++++++++++-------- 3 files changed, 34 insertions(+), 11 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 9e52a52..9a939aa 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -116,6 +116,10 @@ in the example above, but allow things like `CHECK` for a constraint, `FOREIGN KEY` (with a column name), `REFERENCES` (with a pair of column names). See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. +## create-table-as, create-view, and others + +## create-extension + ## create-view `:create-view` accepts a single view name: diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 152999d..a499eff 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -39,7 +39,7 @@ [;; DDL comes first (these don't really have a precedence): :alter-table :add-column :drop-column :modify-column :rename-column :add-index :drop-index :rename-table - :create-table :with-columns :create-view :drop-table + :create-table :create-table-as :with-columns :create-view :drop-table :create-extension :drop-extension ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all @@ -53,7 +53,8 @@ :window :partition-by :order-by :limit :offset :for :values :on-conflict :on-constraint :do-nothing :do-update-set - :returning]) + :returning + :with-data]) (defn- add-clause-before "Low-level helper just to insert a new clause." @@ -599,6 +600,12 @@ i (when as (sql-kw as))]))])) +(defn- format-with-data [k data] + [(str/join " " (remove nil? + [(sql-kw :with) + (when-not data (sql-kw :no)) + (sql-kw :data)]))]) + (defn- format-drop-table [k params] (let [tables (if (sequential? params) params [params]) @@ -655,6 +662,7 @@ :drop-index #'format-selector :rename-table (fn [_ x] (format-selector :rename-to x)) :create-table (fn [_ x] (format-create :table x nil)) + :create-table-as (fn [_ x] (format-create :table x :as)) :create-extension (fn [_ x] (format-create :extension x nil)) :with-columns #'format-table-columns :create-view (fn [_ x] (format-create :view x :as)) @@ -702,7 +710,8 @@ :on-constraint #'format-selector :do-nothing (fn [k _] (vector (sql-kw k))) :do-update-set #'format-do-update-set - :returning #'format-selects})) + :returning #'format-selects + :with-data #'format-with-data})) (assert (= (set @base-clause-order) (set @current-clause-order) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 0177e50..23457b3 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -156,23 +156,27 @@ flag to trigger IF NOT EXISTS in the SQL: (create-table :foo) - (create-table :foo :if-not-exists) - - That second argument can be truthy value but using - that keyword is recommended for clarity." + (create-table :foo :if-not-exists)" {:arglists '([table] [table if-not-exists])} [& args] (generic :create-table args)) +(defn create-table-as + "Accepts a table name to create and optionally a + flag to trigger IF NOT EXISTS in the SQL: + + (create-table-as :foo) + (create-table-as :foo :if-not-exists)" + {:arglists '([table] [table if-not-exists])} + [& args] + (generic :create-table-as args)) + (defn create-extension "Accepts an extension name to create and optionally a flag to trigger IF NOT EXISTS in the SQL: (create-extension :postgis) - (create-extension :postgis :if-not-exists) - - That second argument can be truthy value but using - that keyword is recommended for clarity." + (create-extension :postgis :if-not-exists)" {:arglists '([extension] [extension if-not-exists])} [& args] (generic :create-extension args)) @@ -548,6 +552,12 @@ [& cols] (generic :returning cols)) +(defn with-data + "Accepts a Boolean determining WITH DATA vs WITH NO DATA." + {:arglists '([data?])} + [& args] + (generic-1 :with-data args)) + ;; helpers that produce non-clause expressions -- must be listed below: (defn composite "Accepts any number of SQL expressions and produces From ddebda94813370c120a8dae899f4af9de624ad89 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Mar 2021 11:43:21 -0800 Subject: [PATCH 187/254] Fixes #301 Fixes #306 by expanding drop/create syntax --- doc/clause-reference.md | 2 +- doc/special-syntax.md | 7 ++ src/honey/sql.cljc | 177 +++++++++++++++++++++---------- src/honey/sql/helpers.cljc | 31 +++++- test/honey/sql/helpers_test.cljc | 72 ++++++++++++- 5 files changed, 223 insertions(+), 66 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 9a939aa..4cb1a7a 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -120,7 +120,7 @@ constraint, `FOREIGN KEY` (with a column name), `REFERENCES` ## create-extension -## create-view +## create-view, create-materialized-view `:create-view` accepts a single view name: diff --git a/doc/special-syntax.md b/doc/special-syntax.md index fe47013..54512ab 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -60,6 +60,13 @@ expression (comma-separated, wrapped in parentheses): ;;=> ["(a, b, ?, x + ?)" "red" 1] ``` +## entity + +Accepts a single keyword or symbol argument and produces a +SQL entity. This is intended for use in contexts that would +otherwise produce a sequence of SQL keywords, such as when +constructing DDL statements. + ## inline Accepts a single argument and tries to render it as a diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a499eff..6416b78 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -39,8 +39,10 @@ [;; DDL comes first (these don't really have a precedence): :alter-table :add-column :drop-column :modify-column :rename-column :add-index :drop-index :rename-table - :create-table :create-table-as :with-columns :create-view :drop-table - :create-extension :drop-extension + :create-table :create-table-as :with-columns + :create-view :create-materialized-view :create-extension + :drop-table :drop-view :drop-materialized-view :drop-extension + :refresh-materialized-view ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :select-distinct-on @@ -561,72 +563,110 @@ (let [e (format-entity x {:drop-ns true})] [(str (sql-kw k) " " e " = EXCLUDED." e)]))) -(defn- format-simple-clause [c] +(defn- format-simple-clause [c context] (binding [*inline* true] - (let [[x & y] (format-dsl c)] - (when (seq y) - (throw (ex-info "column/index operations must be simple clauses" - {:clause c :params y}))) - x))) + (let [[sql & params] (format-dsl c)] + (when (seq params) + (throw (ex-info (str "parameters are not accepted in " context) + {:clause c :params params}))) + sql))) + +(defn- format-simple-expr [e context] + (binding [*inline* true] + (let [[sql & params] (format-expr e)] + (when (seq params) + (throw (ex-info (str "parameters are not accepted in " context) + {:expr e :params params}))) + sql))) (defn- format-alter-table [k x] (if (sequential? x) [(str (sql-kw k) " " (format-entity (first x)) (when-let [clauses (next x)] - (str " " (str/join ", " (map #'format-simple-clause clauses)))))] + (str " " (str/join ", " (map #(format-simple-clause % "column/index operations") clauses)))))] [(str (sql-kw k) " " (format-entity x))])) -(defn- destructure-create-item [table] - (let [coll +(defn- format-ddl-options + "Given a sequence of options for a DDL statement (the part that + comes between the entity name being created/dropped and the + remaining part of the statement), render clauses and sequences + of keywords and entity names. Returns a sequence of SQL strings." + [opts context] + (for [opt opts] + (cond (map? opt) + (format-simple-clause opt context) + (sequential? opt) + (str/join " " + (map (fn [e] + (if (ident? e) + (sql-kw e) + (format-simple-expr e context))) + opt)) + :else + (sql-kw opt)))) + +(defn- destructure-create-item [table context] + (let [params (if (sequential? table) table [table]) - ine (last coll) + coll (take-while ident? params) + opts (drop-while ident? params) + ine (last coll) [prequel table ine] (if (= :if-not-exists (sym->kw ine)) [(butlast (butlast coll)) (last (butlast coll)) ine] [(butlast coll) (last coll) nil])] - [(str/join " " (map sql-kw prequel)) - (format-entity table) - (when ine (sql-kw ine))])) + (into [(str/join " " (map sql-kw prequel)) + (format-entity table) + (when ine (sql-kw ine))] + (format-ddl-options opts context)))) -(defn- format-create [k item as] - (let [[pre i ine] (destructure-create-item item)] +(defn- format-create [q k item as] + (let [[pre entity ine & more] + (destructure-create-item item (str (sql-kw q) " options"))] [(str/join " " (remove nil? - [(sql-kw :create) - (when (seq pre) pre) - (sql-kw k) - ine - i - (when as (sql-kw as))]))])) + (-> [(sql-kw q) + (when (and (= :create q) (seq pre)) pre) + (sql-kw k) + ine + (when (and (= :refresh q) (seq pre)) pre) + entity] + (into more) + (conj (when as (sql-kw as))))))])) -(defn- format-with-data [k data] - [(str/join " " (remove nil? - [(sql-kw :with) - (when-not data (sql-kw :no)) - (sql-kw :data)]))]) +(defn- format-with-data [_ data] + (let [data (if (sequential? data) (first data) data)] + [(str/join " " (remove nil? + [(sql-kw :with) + (when-not data (sql-kw :no)) + (sql-kw :data)]))])) -(defn- format-drop-table +(defn- destructure-drop-items [tables context] + (let [params + (if (sequential? tables) + tables + [tables]) + coll (take-while ident? params) + opts (drop-while ident? params) + [if-exists & tables] + (if (#{:if-exists 'if-exists} (first coll)) + coll + (cons nil coll))] + (into [(when if-exists (sql-kw :if-exists)) + (str/join ", " (map #'format-entity tables))] + (format-ddl-options opts context)))) + +(defn- format-drop-items [k params] - (let [tables (if (sequential? params) params [params]) - [if-exists & tables] (if (#{:if-exists 'if-exists} (first tables)) tables (cons nil tables))] - [(str (sql-kw k) " " - (when if-exists (str (sql-kw :if-exists) " ")) - (str/join ", " (map #'format-entity tables)))])) - -(defn- format-simple-expr [e] - (binding [*inline* true] - (let [[x & y] (format-expr e)] - (when (seq y) - (throw (ex-info "column elements must be simple expressions" - {:expr e :params y}))) - x))) + (let [[if-exists tables & more] (destructure-drop-items params "DROP options")] + [(str/join " " (remove nil? (into [(sql-kw k) if-exists tables] more)))])) (defn- format-single-column [xs] - (str/join " " (let [[id & spec] (map #'format-simple-expr xs)] + (str/join " " (let [[id & spec] (map #(format-simple-expr % "column operation") xs)] (cons id (map upper-case spec))))) -(defn- format-table-columns [k xs] +(defn- format-table-columns [_ xs] [(str "(" (str/join ", " (map #'format-single-column xs)) ")")]) @@ -661,13 +701,17 @@ :add-index (fn [_ x] (format-on-expr :add x)) :drop-index #'format-selector :rename-table (fn [_ x] (format-selector :rename-to x)) - :create-table (fn [_ x] (format-create :table x nil)) - :create-table-as (fn [_ x] (format-create :table x :as)) - :create-extension (fn [_ x] (format-create :extension x nil)) + :create-table (fn [_ x] (format-create :create :table x nil)) + :create-table-as (fn [_ x] (format-create :create :table x :as)) + :create-extension (fn [_ x] (format-create :create :extension x nil)) :with-columns #'format-table-columns - :create-view (fn [_ x] (format-create :view x :as)) - :drop-table #'format-drop-table - :drop-extension #'format-drop-table + :create-view (fn [_ x] (format-create :create :view x :as)) + :create-materialized-view (fn [_ x] (format-create :create :materialized-view x :as)) + :drop-table #'format-drop-items + :drop-extension #'format-drop-items + :drop-view #'format-drop-items + :drop-materialized-view #'format-drop-items + :refresh-materialized-view (fn [_ x] (format-create :refresh :materialized-view x nil)) :nest (fn [_ x] (format-expr x)) :with #'format-with :with-recursive #'format-with @@ -737,9 +781,10 @@ [statement-map & [{:keys [aliased nested pretty]}]] (let [[sqls params leftover] (reduce (fn [[sql params leftover] k] - (if-let [xs (or (k statement-map) - (let [s (kw->sym k)] - (get statement-map s)))] + (if-some [xs (if-some [xs (k statement-map)] + xs + (let [s (kw->sym k)] + (get statement-map s)))] (let [formatter (k @clause-format) [sql' & params'] (formatter k xs)] [(conj sql sql') @@ -804,22 +849,35 @@ (defn- function-0 [k xs] [(str (sql-kw k) (when (seq xs) - (str "(" (str/join ", " (map #'format-simple-expr xs)) ")")))]) + (str "(" + (str/join ", " + (map #(format-simple-expr % "column/index operation") + xs)) + ")")))]) (defn- function-1 [k xs] [(str (sql-kw k) (when (seq xs) - (str " " (format-simple-expr (first xs)) + (str " " (format-simple-expr (first xs) + "column/index operation") (when-let [args (next xs)] - (str "(" (str/join ", " (map #'format-simple-expr args)) ")")))))]) + (str "(" + (str/join ", " + (map #(format-simple-expr % "column/index operation") + args)) + ")")))))]) (defn- function-1-opt [k xs] [(str (sql-kw k) (when (seq xs) (str (when-let [e (first xs)] - (str " " (format-simple-expr e))) + (str " " (format-simple-expr e "column/index operation"))) (when-let [args (next xs)] - (str "(" (str/join ", " (map #'format-simple-expr args)) ")")))))]) + (str "(" + (str/join ", " + (map #(format-simple-expr % "column/index operation") + args)) + ")")))))]) (def ^:private special-syntax (atom @@ -840,6 +898,9 @@ :primary-key #'function-0 :references #'function-1 :unique #'function-1-opt + ;; used in DDL to force rendering as a SQL entity instead + ;; of a SQL keyword: + :entity (fn [_ [e]] [(format-entity e)]) :array (fn [_ [arr]] (let [[sqls params] (format-expr-list arr)] diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 23457b3..222ab61 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -65,7 +65,7 @@ (helper-merge {} k args))) (defn- generic-1 [k [data arg]] - (if arg + (if (some? arg) (assoc data k arg) (assoc {} k data))) @@ -213,8 +213,19 @@ (-> (create-view :cities) (select :*) (from :city))" + {:arglists '([view])} [& args] - (generic-1 :create-view args)) + (generic :create-view args)) + +(defn create-materialized-view + "Accepts a single view name to create. + + (-> (create-materialized-view :cities) + (select :*) (from :city)) + (with-data true)" + {:arglists '([view])} + [& args] + (generic :create-materialized-view args)) (defn drop-table "Accepts one or more table names to drop. @@ -228,6 +239,22 @@ [& extensions] (generic :drop-extension extensions)) +(defn drop-view + "Accepts one or more view names to drop." + [& views] + (generic :drop-view views)) + +(defn drop-materialized-view + "Accepts one or more materialied view names to drop." + [& views] + (generic :drop-materialized-view views)) + +(defn refresh-materialized-view + "Accepts a materialied view name to refresh." + {:arglists '([view])} + [& views] + (generic :refresh-materialized-view views)) + (defn nest [& args] (generic :nest args)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index c59638f..686e8cf 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -6,13 +6,15 @@ :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] [honey.sql.helpers - :refer [add-column add-index alter-table columns create-table create-view + :refer [add-column add-index alter-table columns create-table create-table-as create-view + create-materialized-view drop-view drop-materialized-view cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into join-by join left-join limit offset on-conflict order-by - over partition-by + over partition-by refresh-materialized-view rename-column rename-table returning right-join - select select-distinct values where window with with-columns]])) + select select-distinct values where window with with-columns + with-data]])) (deftest test-select (let [m1 (-> (with [:cte (-> (select :*) @@ -367,6 +369,54 @@ (from :cities) (where [:= :metroflag "y"]))) ["CREATE VIEW metro AS SELECT * FROM cities WHERE metroflag = ?" "y"])) + (is (= (sql/format (-> (create-table-as :metro :if-not-exists) + (select :*) + (from :cities) + (where [:= :metroflag "y"]) + (with-data false))) + ["CREATE TABLE IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"])) + (is (= (sql/format (-> (create-materialized-view :metro :if-not-exists) + (select :*) + (from :cities) + (where [:= :metroflag "y"]) + (with-data false))) + ["CREATE MATERIALIZED VIEW IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA" "y"])) + (is (= (sql/format (-> (create-table-as :metro :if-not-exists + (columns :foo :bar :baz) + [:tablespace [:entity :quux]]) + (select :*) + (from :cities) + (where [:= :metroflag "y"]) + (with-data false))) + [(str "CREATE TABLE IF NOT EXISTS metro" + " (foo, bar, baz) TABLESPACE quux" + " AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"])) + (is (= (sql/format (-> (create-materialized-view :metro :if-not-exists + (columns :foo :bar :baz) + [:tablespace [:entity :quux]]) + (select :*) + (from :cities) + (where [:= :metroflag "y"]) + (with-data false))) + [(str "CREATE MATERIALIZED VIEW IF NOT EXISTS metro" + " (foo, bar, baz) TABLESPACE quux" + " AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"])) + (is (= (sql/format {:create-materialized-view [:metro :if-not-exists] + :select [:*] + :from :cities + :where [:= :metroflag "y"] + :with-data true}) + ["CREATE MATERIALIZED VIEW IF NOT EXISTS metro AS SELECT * FROM cities WHERE metroflag = ? WITH DATA" "y"])) + (is (= (sql/format {:create-materialized-view [:metro :if-not-exists + (columns :foo :bar :baz) + [:tablespace [:entity :quux]]] + :select [:*] + :from :cities + :where [:= :metroflag "y"] + :with-data false}) + [(str "CREATE MATERIALIZED VIEW IF NOT EXISTS metro" + " (foo, bar, baz) TABLESPACE quux" + " AS SELECT * FROM cities WHERE metroflag = ? WITH NO DATA") "y"])) (is (= (sql/format (-> (create-table :films) (with-columns [:id :int :unsigned :auto-increment] @@ -391,20 +441,32 @@ ["DROP TABLE foo"])) (is (= (sql/format {:drop-table [:if-exists :foo]}) ["DROP TABLE IF EXISTS foo"])) + (is (= (sql/format {:drop-view [:if-exists :foo]}) + ["DROP VIEW IF EXISTS foo"])) + (is (= (sql/format {:drop-materialized-view [:if-exists :foo]}) + ["DROP MATERIALIZED VIEW IF EXISTS foo"])) + (is (= (sql/format {:refresh-materialized-view [:concurrently :foo] + :with-data true}) + ["REFRESH MATERIALIZED VIEW CONCURRENTLY foo WITH DATA"])) (is (= (sql/format '{drop-table (if-exists foo)}) ["DROP TABLE IF EXISTS foo"])) (is (= (sql/format {:drop-table [:foo :bar]}) ["DROP TABLE foo, bar"])) (is (= (sql/format {:drop-table [:if-exists :foo :bar]}) ["DROP TABLE IF EXISTS foo, bar"])) + (is (= (sql/format {:drop-table [:if-exists :foo :bar [:cascade]]}) + ["DROP TABLE IF EXISTS foo, bar CASCADE"])) (is (= (sql/format (drop-table :foo)) ["DROP TABLE foo"])) (is (= (sql/format (drop-table :if-exists :foo)) ["DROP TABLE IF EXISTS foo"])) + (is (= (sql/format (-> (refresh-materialized-view :concurrently :foo) + (with-data true))) + ["REFRESH MATERIALIZED VIEW CONCURRENTLY foo WITH DATA"])) (is (= (sql/format (drop-table :foo :bar)) ["DROP TABLE foo, bar"])) - (is (= (sql/format (drop-table :if-exists :foo :bar)) - ["DROP TABLE IF EXISTS foo, bar"]))) + (is (= (sql/format (drop-table :if-exists :foo :bar [:cascade])) + ["DROP TABLE IF EXISTS foo, bar CASCADE"]))) (deftest issue-293-alter-table (is (= (sql/format (-> (alter-table :fruit) From d35d9141bc611d47bbdc00d84c444f9141f596cc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Mar 2021 15:39:54 -0800 Subject: [PATCH 188/254] Fixes #280 by adding [:escape pattern chars] --- CHANGELOG.md | 4 ++++ doc/special-syntax.md | 5 +++++ src/honey/sql.cljc | 7 +++++++ test/honey/sql_test.cljc | 6 ++++++ 4 files changed, 22 insertions(+) diff --git a/CHANGELOG.md b/CHANGELOG.md index b294c8e..8b1ffbd 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,10 +1,14 @@ # Changes * 2.0.0-alpha3 in progress + * Support much richer range of syntax on `CREATE`/`DROP` statements in general, including columns, `TABLESPACE`, `CASCADE`, `WITH [NO] DATA`, etc. + * Fix #306 by supporting `CREATE TABLE .. AS ..`. * Fix #305 by supporting more complex join clauses. + * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). + * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. * 2.0.0-alpha2 (for early testing) diff --git a/doc/special-syntax.md b/doc/special-syntax.md index 54512ab..e191a82 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -67,6 +67,11 @@ SQL entity. This is intended for use in contexts that would otherwise produce a sequence of SQL keywords, such as when constructing DDL statements. +## escape + +Intended to be used with regular expression patterns to +specify the escape characters (if any). + ## inline Accepts a single argument and tries to render it as a diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 6416b78..5eeb92d 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -943,6 +943,13 @@ (fn [_ [& args]] (let [[sqls params] (format-expr-list args)] (into [(str "(" (str/join ", " sqls) ")")] params))) + :escape + (fn [_ [pattern escape-chars]] + (let [[sql-p & params-p] (format-expr pattern) + [sql-e & params-e] (format-expr escape-chars)] + (-> [(str sql-p " " (sql-kw :escape) " " sql-e)] + (into params-p) + (into params-e)))) :inline (fn [_ [x]] (if (sequential? x) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3a475b6..dfdb7e8 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -294,6 +294,12 @@ [[1 2] [3 4] [5 6]])}]]}) ["WITH bar (spam, eggs) AS (VALUES (1, 2), (3, 4), (5, 6)) (SELECT foo FROM bar1) UNION (SELECT foo FROM bar2)"])))) +(deftest similar-regex-tests + (testing "basic similar to" + (is (= (format {:select :* :from :foo + :where [:similar-to :foo [:escape "bar" [:inline "*"]]]}) + ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"])))) + (deftest former-parameterizer-tests-where-and ;; I have no plans for positional parameters -- I just don't see the point #_(testing "should ignore a nil predicate -- fail: postgresql parameterizer" From dc6a3662f0225db0404813c6bd2e6284f8814a81 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Mar 2021 16:13:52 -0800 Subject: [PATCH 189/254] Fixes #303 by adding ON DUPLICATE KEY UPDATE --- CHANGELOG.md | 1 + doc/clause-reference.md | 4 ++++ src/honey/sql.cljc | 4 +++- src/honey/sql/helpers.cljc | 4 ++++ test/honey/sql/helpers_test.cljc | 26 ++++++++++++++++++++++++-- 5 files changed, 36 insertions(+), 3 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 8b1ffbd..41101fb 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -4,6 +4,7 @@ * Support much richer range of syntax on `CREATE`/`DROP` statements in general, including columns, `TABLESPACE`, `CASCADE`, `WITH [NO] DATA`, etc. * Fix #306 by supporting `CREATE TABLE .. AS ..`. * Fix #305 by supporting more complex join clauses. + * Fix #303 by supporting MySQL's `ON DUPLICATE KEY UPDATE`. * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 4cb1a7a..0459e21 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -715,6 +715,10 @@ user=> (sql/format {:insert-into :companies ["INSERT INTO companies (name) VALUES (?) ON CONFLICT ON CONSTRAINT name_idx DO NOTHING" "Microsoft"] ``` +## on-duplicate-key-update + +This is the MySQL equivalent of `on-update-set` described above. + ## returning `:returning` accepts a single sequence argument that lists diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5eeb92d..b7f29d7 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -54,7 +54,7 @@ :where :group-by :having :window :partition-by :order-by :limit :offset :for :values - :on-conflict :on-constraint :do-nothing :do-update-set + :on-conflict :on-constraint :do-nothing :do-update-set :on-duplicate-key-update :returning :with-data]) @@ -754,6 +754,8 @@ :on-constraint #'format-selector :do-nothing (fn [k _] (vector (sql-kw k))) :do-update-set #'format-do-update-set + ;; MySQL-specific but might as well be always enabled: + :on-duplicate-key-update #'format-do-update-set :returning #'format-selects :with-data #'format-with-data})) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 222ab61..844c619 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -569,6 +569,10 @@ [& args] (generic :do-update-set args)) +(defn on-duplicate-key-update + [& args] + (generic :on-duplicate-key-update args)) + (defn returning "Accepts any number of column names to return from an insert operation: diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 686e8cf..c894d08 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -10,8 +10,9 @@ create-materialized-view drop-view drop-materialized-view cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into - join-by join left-join limit offset on-conflict order-by - over partition-by refresh-materialized-view + join-by join left-join limit offset on-conflict + on-duplicate-key-update + order-by over partition-by refresh-materialized-view rename-column rename-table returning right-join select select-distinct values where window with with-columns with-data]])) @@ -649,3 +650,24 @@ (f {k [:and [:a] [:b]]} :or [:x] [:y])))))))) + +(deftest mysql-on-duplicate-key-update + (testing "From https://www.mysqltutorial.org/mysql-insert-or-update-on-duplicate-key-update" + (is (= (sql/format (-> (insert-into :device) + (columns :name) + (values [["Printer"]]) + (on-duplicate-key-update {:name "Printer"}))) + ["INSERT INTO device (name) VALUES (?) ON DUPLICATE KEY UPDATE name = ?" + "Printer" "Printer"])) + (is (= (sql/format (-> (insert-into :device) + (columns :id :name) + (values [[4 "Printer"]]) + (on-duplicate-key-update {:name "Central Printer"}))) + ["INSERT INTO device (id, name) VALUES (?, ?) ON DUPLICATE KEY UPDATE name = ?" + 4 "Printer" "Central Printer"])) + (is (= (sql/format (-> (insert-into :table) + (columns :c1) + (values [[42]]) + (on-duplicate-key-update {:c1 [:+ [:values :c1] 1]}))) + ["INSERT INTO table (c1) VALUES (?) ON DUPLICATE KEY UPDATE c1 = VALUES(c1) + ?" + 42 1])))) \ No newline at end of file From 479008c294194ce9249dc98749153f97a695b810 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 12 Mar 2021 18:54:19 -0800 Subject: [PATCH 190/254] Address #292 by starting to support SELECT TOP --- CHANGELOG.md | 1 + src/honey/sql.cljc | 32 ++++++++++++++++++++++++++++++-- src/honey/sql/helpers.cljc | 15 +++++++++++++++ test/honey/sql/helpers_test.cljc | 6 +++++- 4 files changed, 51 insertions(+), 3 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 41101fb..b72a7e1 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -8,6 +8,7 @@ * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). + * Add support for `SELECT TOP` (#292). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b7f29d7..18a9f2f 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -45,7 +45,7 @@ :refresh-materialized-view ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all - :select :select-distinct :select-distinct-on + :select :select-distinct :select-distinct-on :select-top :select-distinct-top :insert-into :update :delete :delete-from :truncate :columns :set :from :using :join-by @@ -298,7 +298,7 @@ k) xs)) -(defn- format-selects-on [k xs] +(defn- format-selects-on [_ xs] (let [[on & cols] xs [sql & params] (format-expr (into [:distinct-on] on)) @@ -309,6 +309,32 @@ cols)] (-> [sql'] (into params) (into params')))) +(defn- format-select-top [k xs] + (let [[top & cols] xs + [top & parts] + (if (sequential? top) + ;; could be an expression or a number followed by :percent :with-ties + (let [top-q? #(and (ident? %) + (#{:percent :with-ties} (sym->kw %))) + r-top (reverse top) + top-quals (take-while top-q? r-top) + top-list (drop-while top-q? r-top)] + (if (seq top-quals) + (if (= 1 (count top-list)) + (into (vec top-list) (reverse top-quals)) + (throw (ex-info "unparseable TOP expression" + {:top top}))) + [top])) + [top]) + [sql & params] + (format-expr top) + [sql' & params'] + (format-selects-common + (str (sql-kw k) " " sql (str/join " " (map sql-kw parts))) + true + cols)] + (-> [sql'] (into params) (into params')))) + (defn- format-with-part [x] (if (sequential? x) (let [[sql & params] (format-dsl (second x))] @@ -723,6 +749,8 @@ :select #'format-selects :select-distinct #'format-selects :select-distinct-on #'format-selects-on + :select-top #'format-select-top + :select-distinct-top #'format-select-top :insert-into #'format-insert :update #'format-selector :delete #'format-selects diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 844c619..6a90f04 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -331,6 +331,21 @@ [& args] (generic :select-distinct-on args)) +(defn select-top + "Accepts a TOP expression, followed by any number of + column names, or column/alias pairs, or SQL expressions + (optionally aliased), as for `select`. The TOP expression + can be a simple numeric expression, or a sequence with + a numeric expression followed by keywords (or symbols) + for PERCENT and/or WITH TIES." + [& args] + (generic :select-top args)) + +(defn select-distinct-top + "Like `select-top` but produces SELECT DISTINCT TOP..." + [& args] + (generic :select-distinct-top args)) + (defn insert-into "Accepts a table name or a table/alias pair. That can optionally be followed by a collection of diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index c894d08..583e7ce 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -14,7 +14,8 @@ on-duplicate-key-update order-by over partition-by refresh-materialized-view rename-column rename-table returning right-join - select select-distinct values where window with with-columns + select select-distinct select-top select-distinct-top + values where window with with-columns with-data]])) (deftest test-select @@ -78,6 +79,9 @@ ;; to enable :lock :dialect :mysql :quoted false})))))) +(deftest select-top-tests + (is true)) + (deftest join-by-test (testing "Natural JOIN orders" (is (= ["SELECT * FROM foo INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y"] From 6b070df52c1707d420d06854a7cc1c0f0fc6159f Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 12:10:42 -0800 Subject: [PATCH 191/254] Finish off TOP implementation #292 --- doc/clause-reference.md | 2 ++ src/honey/sql.cljc | 4 +++- test/honey/sql/helpers_test.cljc | 15 ++++++++++++++- 3 files changed, 19 insertions(+), 2 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 0459e21..21a0458 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -232,6 +232,8 @@ user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]] HoneySQL does not yet support `SELECT .. INTO ..` or `SELECT .. BULK COLLECT INTO ..`. +## select-top, select-distinct-top + ## select-distinct-on Similar to `:select-distinct` above but the first element diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 18a9f2f..a193595 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -330,7 +330,9 @@ (format-expr top) [sql' & params'] (format-selects-common - (str (sql-kw k) " " sql (str/join " " (map sql-kw parts))) + (str (sql-kw k) "(" sql ")" + (when (seq parts) " ") + (str/join " " (map sql-kw parts))) true cols)] (-> [sql'] (into params) (into params')))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 583e7ce..c8e322f 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -80,7 +80,20 @@ :dialect :mysql :quoted false})))))) (deftest select-top-tests - (is true)) + (testing "Basic TOP syntax" + (is (= ["SELECT TOP(?) foo FROM bar ORDER BY quux ASC" 10] + (sql/format {:select-top [10 :foo] :from :bar :order-by [:quux]}))) + (is (= ["SELECT TOP(?) foo FROM bar ORDER BY quux ASC" 10] + (sql/format (-> (select-top 10 :foo) + (from :bar) + (order-by :quux)))))) + (testing "Expanded TOP syntax" + (is (= ["SELECT TOP(?) PERCENT WITH TIES foo, baz FROM bar ORDER BY quux ASC" 10] + (sql/format {:select-top [[10 :percent :with-ties] :foo :baz] :from :bar :order-by [:quux]}))) + (is (= ["SELECT TOP(?) PERCENT WITH TIES foo, baz FROM bar ORDER BY quux ASC" 10] + (sql/format (-> (select-top [10 :percent :with-ties] :foo :baz) + (from :bar) + (order-by :quux))))))) (deftest join-by-test (testing "Natural JOIN orders" From 82ee465820e7893eeabf8256a8e621798643806c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 12:36:25 -0800 Subject: [PATCH 192/254] Fixes #292 by supporting offset/fetch --- CHANGELOG.md | 2 +- doc/clause-reference.md | 21 ++++++++++++++------- doc/differences-from-1-x.md | 2 +- doc/getting-started.md | 3 +-- src/honey/sql.cljc | 11 ++++------- src/honey/sql/helpers.cljc | 24 ++++++++++++++++++++++-- 6 files changed, 43 insertions(+), 20 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index b72a7e1..f0b0627 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -8,7 +8,7 @@ * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). - * Add support for `SELECT TOP` (#292). + * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 21a0458..78e153d 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -570,18 +570,27 @@ user=> (sql/format {:select [:*] :from :table ["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"] ``` -## limit, offset (MySQL) +## limit, offset, fetch -Both `:limit` and `:offset` expect a single SQL expression: +Some databases, including MySQL, support `:limit` and `:offset` +for paginated queries, other databases support `:offset` and +`fetch` for that (which is ANSI-compliant and should be +preferred if your database supports it). All three expect a +single SQL expression: ```clojure user=> (sql/format {:select [:id :name] :from [:table] - :limit 20 :offset 20}) -["SELECT id, name FROM table LIMIT ? OFFSET ?" 20 20] + :limit 10 :offset 20}) +["SELECT id, name FROM table LIMIT ? OFFSET ?" 10 20] +user=> (sql/format {:select [:id :name] + :from [:table] + :offset 20 :fetch 10}) +["SELECT id, name FROM table OFFSET ? FETCH ? ONLY" 20 10] ``` -> Note: In the prerelease, these MySQL-specific clauses are in the default dialect but these will be moved to the `:mysql` dialect. +All three are available in all dialects for HoneySQL so it +is up to you to choose the correct pair for your database. ## for @@ -627,8 +636,6 @@ expected to be just one of those three mentioned above). The syntax accepted for MySQL's `:lock` is exactly the same as the `:for` clause above. -> Note: In the prerelease, this MySQL-specific clauses is in the default dialect but this will be moved to the `:mysql` dialect. - ## values `:values` accepts either a sequence of hash maps representing diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 3277b6d..4f63c8d 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -74,7 +74,7 @@ Other `honeysql.core` functions that no longer exist include: `build`, `qualify` You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialect!` function (which sets a default dialect for all `format` operations) or by passing the new `:dialect` option to the `format` function. `:ansi` is the default dialect (which will mostly incorporate PostgreSQL usage over time). Other dialects supported are `:mysql` (which has a different quoting strategy and uses a different ranking for the `:set` clause), `:oracle` (which is essentially the `:ansi` dialect but will control other things over time), and `:sqlserver` (which is essentially the `:ansi` dialect but with a different quoting strategy). Other dialects and changes may be added over time. -> Note: `:limit` and `:offset` are currently in the default `:ansi` dialect even though they are MySQL-specific. This will change as the dialects are fleshed out. I plan to add `:top` for `:sqlserver` and `:offset` / `:fetch` for `:ansi`, at which point `:limit` / `:offset` will become MySQL-only. +> Note: in general, all clauses are available in all dialects in HoneySQL unless the syntax of the clauses conflict between dialects (currently, no such clauses exist). The `:mysql` dialect is the only one so far that changes the priority ordering of a few clauses. ## Option Changes diff --git a/doc/getting-started.md b/doc/getting-started.md index f49781c..5455c3a 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -259,8 +259,7 @@ The `:sqlserver` dialect uses `[`..`]` and the `:mysql` dialect uses ```..```. In addition, the `:oracle` dialect disables `AS` in aliases. Currently, the only dialect that has substantive differences from -the others is `:mysql` which has a `:lock` clause (that is very -similar to the ANSI `:for` clause) and for which the `:set` clause +the others is `:mysql` for which the `:set` clause has a different precedence than ANSI SQL. You can change the dialect globally using the `set-dialect!` function, diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a193595..0f1277e 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -53,7 +53,7 @@ :cross-join :where :group-by :having :window :partition-by - :order-by :limit :offset :for :values + :order-by :limit :offset :fetch :for :lock :values :on-conflict :on-constraint :do-nothing :do-update-set :on-duplicate-key-update :returning :with-data]) @@ -79,14 +79,9 @@ :sqlserver {:quote #(str \[ % \])} :mysql {:quote #(str \` % \`) :clause-order-fn (fn [order] - ;; :lock is like :for - (swap! clause-format assoc :lock - (get @clause-format :for)) ;; MySQL :set has different priority - ;; and :lock is between :for and :values (-> (filterv (complement #{:set}) order) - (add-clause-before :set :where) - (add-clause-before :lock :values)))} + (add-clause-before :set :where)))} :oracle {:quote #(str \" % \") :as false}}) ; should become defonce @@ -778,7 +773,9 @@ :order-by #'format-order-by :limit #'format-on-expr :offset #'format-on-expr + :fetch #'format-on-expr :for #'format-lock-strength + :lock #'format-lock-strength :values #'format-values :on-conflict #'format-on-conflict :on-constraint #'format-selector diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 6a90f04..28d1633 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -527,13 +527,18 @@ (limit 40) Produces: LIMIT ? - Parameters: 40" + Parameters: 40 + + The two-argument syntax is not supported: use `offset` + instead: + + `LIMIT 20,10` is equivalent to `LIMIT 10 OFFSET 20`" {:arglists '([limit])} [& args] (generic-1 :limit args)) (defn offset - "Specific to MySQL, accepts a single SQL expression: + "Accepts a single SQL expression: (offset 10) @@ -543,10 +548,25 @@ [& args] (generic-1 :offset args)) +(defn fetch + "Accepts a single SQL expression: + + (fetch 10) + + Produces: FETCH ? ONLY + Parameters: 10" + {:arglists '([offset])} + [& args] + (generic-1 :offset args)) + (defn for [& args] (generic-1 :for args)) +(defn lock + [& args] + (generic-1 :lock args)) + (defn values "Accepts a single argument: a collection of row values. Each row value can be either a sequence of column values From cff1e5b43c52ae5eb1e0b240e7526ebd6071b7f6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 13:13:35 -0800 Subject: [PATCH 193/254] Fixes #284 by adding lateral expression syntax --- CHANGELOG.md | 1 + doc/special-syntax.md | 5 +++++ src/honey/sql.cljc | 15 ++++++++++++-- src/honey/sql/helpers.cljc | 15 +++++++++++++- test/honey/sql/helpers_test.cljc | 34 +++++++++++++++++++++++++++++++- 5 files changed, 66 insertions(+), 4 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index f0b0627..658c011 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -9,6 +9,7 @@ * Add tests to confirm #299 does not affect v2. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. + * Fix #284 by adding support for `LATERAL` (as special syntax, with a helper). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. diff --git a/doc/special-syntax.md b/doc/special-syntax.md index e191a82..98f8c2e 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -98,6 +98,11 @@ that represents a time unit. Produces an `INTERVAL` expression: ;;=> ["DATE_ADD(NOW(), INTERVAL ? DAYS)" 30] ``` +## lateral + +Accepts a single argument that can be a (`SELECT`) clause or +a (function call) expression. + ## lift Used to wrap a Clojure value that should be passed as a diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 0f1277e..e3d4573 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -111,6 +111,10 @@ #?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US)))) :cljs str/upper-case)) +(def ^:private keep-hyphen + "The set of symbols that should not have `-` replaced by space." + #{"-" "<->"}) + (defn sql-kw "Given a keyword, return a SQL representation of it as a string. @@ -120,7 +124,7 @@ Any namespace qualifier is ignored." [k] (-> k (name) (upper-case) - (as-> s (if (= "-" s) s (str/replace s "-" " "))))) + (as-> s (if (keep-hyphen s) s (str/replace s "-" " "))))) (defn- sym->kw "Given a symbol, produce a keyword, retaining the namespace @@ -841,7 +845,7 @@ :regex :regexp}) (def ^:private infix-ops - (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" + (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "<->" "like" "not-like" "regexp" "ilike" "not-ilike" "similar-to" "not-similar-to" "is" "is-not" "not=" "!=" "regex"} @@ -988,6 +992,13 @@ (fn [_ [n units]] (let [[sql & params] (format-expr n)] (into [(str "INTERVAL " sql " " (sql-kw units))] params))) + :lateral + (fn [_ [clause-or-expr]] + (if (map? clause-or-expr) + (let [[sql & params] (format-dsl clause-or-expr)] + (into [(str "LATERAL (" sql ")")] params)) + (let [[sql & params] (format-expr clause-or-expr)] + (into [(str "LATERAL " sql)] params)))) :lift (fn [_ [x]] (if *inline* diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 28d1633..9534845 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -636,6 +636,19 @@ [& args] (into [:composite] args)) +(defn lateral + "Accepts a SQL clause or a SQL expression: + + (lateral (-> (select '*) (from 'foo))) + (lateral '(calc_value bar)) + + Produces: + LATERAL (SELECT * FROM foo) + LATERAL CALC_VALUE(bar)" + {:arglists '([clause-or-expression])} + [& args] + (into [:lateral] args)) + ;; to make this easy to use in a select, wrap it so it becomes a function: (defn over "Accepts any number of OVER clauses, each of which @@ -702,5 +715,5 @@ #?(:clj (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order - :composite :over :upsert)) + :composite :lateral :over :upsert)) (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index c8e322f..b5d158e 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -10,7 +10,7 @@ create-materialized-view drop-view drop-materialized-view cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into - join-by join left-join limit offset on-conflict + join-by join lateral left-join limit offset on-conflict on-duplicate-key-update order-by over partition-by refresh-materialized-view rename-column rename-table returning right-join @@ -95,6 +95,38 @@ (from :bar) (order-by :quux))))))) +(deftest from-expression-tests + (testing "FROM can be a function invocation" + (is (= ["SELECT foo, bar FROM F(?) AS x" 1] + (sql/format {:select [:foo :bar] :from [[[:f 1] :x]]})))) + ;; these two examples are from https://www.postgresql.org/docs/9.3/queries-table-expressions.html#QUERIES-LATERAL + (testing "FROM can be a LATERAL select" + (is (= ["SELECT * FROM foo, LATERAL (SELECT * FROM bar WHERE bar.id = foo.bar_id) AS ss"] + (sql/format {:select :* + :from [:foo + [[:lateral {:select :* + :from :bar + :where [:= :bar.id :foo.bar_id]}] :ss]]})))) + (testing "FROM can be a LATERAL expression" + (is (= [(str "SELECT p1.id, p2.id, v1, v2" + " FROM polygons AS p1, polygons AS p2," + " LATERAL VERTICES(p1.poly) AS v1," + " LATERAL VERTICES(p2.poly) AS v2" + " WHERE ((v1 <-> v2) < ?) AND (p1.id <> p2.id)") 10] + (sql/format {:select [:p1.id :p2.id :v1 :v2] + :from [[:polygons :p1] [:polygons :p2] + [[:lateral [:vertices :p1.poly]] :v1] + [[:lateral [:vertices :p2.poly]] :v2]] + :where [:and [:< [:<-> :v1 :v2] 10] [:!= :p1.id :p2.id]]}))) + (is (= [(str "SELECT m.name" + " FROM manufacturers AS m" + " LEFT JOIN LATERAL GET_PRODUCT_NAMES(m.id) AS pname ON TRUE" + " WHERE pname IS NULL")] + (sql/format {:select :m.name + :from [[:manufacturers :m]] + :left-join [[[:lateral [:get_product_names :m.id]] :pname] true] + :where [:= :pname nil]}))))) + (deftest join-by-test (testing "Natural JOIN orders" (is (= ["SELECT * FROM foo INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y"] From 16d04a1dfd820e9329aeaa19a391f6a1d0450f2c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 13:42:08 -0800 Subject: [PATCH 194/254] Fixes #297 by adding into/bulk-collect-into --- CHANGELOG.md | 1 + doc/clause-reference.md | 22 ++++++++++++++++++++++ src/honey/sql.cljc | 14 ++++++++++++++ src/honey/sql/helpers.cljc | 32 +++++++++++++++++++++++--------- test/honey/sql/helpers_test.cljc | 23 ++++++++++++++++++++++- 5 files changed, 82 insertions(+), 10 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 658c011..ea35cc5 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -7,6 +7,7 @@ * Fix #303 by supporting MySQL's `ON DUPLICATE KEY UPDATE`. * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. + * Fix #297 by adding both `SELECT .. INTO ..` and `SELECT .. BULK COLLECT INTO ..`. * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. * Fix #284 by adding support for `LATERAL` (as special syntax, with a helper). diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 78e153d..21a6047 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -247,6 +247,28 @@ user=> (sql/format '{select-distinct-on [[a b] c d] ["SELECT DISTINCT ON(a, b) c, d FROM table"] ``` +## into + +Used for selecting rows into a new table, optional in another database: + +```clojure +user=> (sql/format '{select * into newtable from mytable}) +["SELECT * INTO newtable FROM mytable"] +user=> (sql/format '{select * into [newtable otherdb] from mytable}) +["SELECT * INTO newtable IN otherdb FROM mytable"] +``` + +## bulk-collect-into + +Used for selecting rows into an array variable, with an optional limit: + +```clojure +user=> (sql/format '{select * bulk-collect-into arrv from mytable}) +["SELECT * BULK COLLECT INTO arrv FROM mytable"] +user=> (sql/format '{select * bulk-collect-into [arrv 100] from mytable}) +["SELECT * BULK COLLECT INTO arrv LIMIT ? FROM mytable" 100] +``` + ## insert-into There are three use cases with `:insert-into`. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index e3d4573..a6cadb4 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -46,6 +46,7 @@ ;; then SQL clauses in priority order: :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :select-distinct-on :select-top :select-distinct-top + :into :bulk-collect-into :insert-into :update :delete :delete-from :truncate :columns :set :from :using :join-by @@ -336,6 +337,17 @@ cols)] (-> [sql'] (into params) (into params')))) +(defn- format-select-into [k xs] + (let [[v e] (if (sequential? xs) xs [xs]) + [sql & params] (when e (format-expr e))] + (into [(str (sql-kw k) " " (format-entity v) + (when sql + (str " " + (sql-kw (if (= :into k) :in :limit)) + " " + sql)))] + params))) + (defn- format-with-part [x] (if (sequential? x) (let [[sql & params] (format-dsl (second x))] @@ -752,6 +764,8 @@ :select-distinct-on #'format-selects-on :select-top #'format-select-top :select-distinct-top #'format-select-top + :into #'format-select-into + :bulk-collect-into #'format-select-into :insert-into #'format-insert :update #'format-selector :delete #'format-selects diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 9534845..9eeb1db 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -2,13 +2,14 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." - (:refer-clojure :exclude [update set group-by for partition-by]) - (:require [honey.sql])) + (:refer-clojure :exclude [into update set group-by for partition-by]) + (:require [clojure.core :as c] + [honey.sql])) ;; implementation helpers: (defn- default-merge [current args] - (into (vec current) args)) + (c/into (vec current) args)) (defn- and-merge [current arg] @@ -16,11 +17,11 @@ (ident? (first arg)) (#{:and :or} (keyword (first arg))))] (cond (= conj' (first current)) - (into (vec current) (rest arg)) + (c/into (vec current) (rest arg)) (seq current) - (into [conj' current] (rest arg)) + (c/into [conj' current] (rest arg)) :else - (into [conj'] (rest arg))) + (c/into [conj'] (rest arg))) (cond (#{:and 'and} (first current)) (conj (vec current) arg) (seq current) @@ -346,6 +347,19 @@ [& args] (generic :select-distinct-top args)) +(defn into + "Accepts table name, optionally followed a database name." + {:arglist '([table] [table dbname])} + [& args] + (generic :into args)) + +(defn bulk-collect-into + "Accepts a variable name, optionally followed by a limit + expression." + {:arglist '([varname] [varname n])} + [& args] + (generic :bulk-collect-into args)) + (defn insert-into "Accepts a table name or a table/alias pair. That can optionally be followed by a collection of @@ -634,7 +648,7 @@ Produces: (a, ?) Parameters: 42" [& args] - (into [:composite] args)) + (c/into [:composite] args)) (defn lateral "Accepts a SQL clause or a SQL expression: @@ -647,7 +661,7 @@ LATERAL CALC_VALUE(bar)" {:arglists '([clause-or-expression])} [& args] - (into [:lateral] args)) + (c/into [:lateral] args)) ;; to make this easy to use in a select, wrap it so it becomes a function: (defn over @@ -660,7 +674,7 @@ Produces: SELECT id, AVG(salary) OVER ()PARTITION BY department)" [& args] - [(into [:over] args)]) + [(c/into [:over] args)]) ;; this helper is intended to ease the migration from nilenso: (defn upsert diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index b5d158e..21b2e38 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -5,9 +5,10 @@ (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] - [honey.sql.helpers + [honey.sql.helpers :as h :refer [add-column add-index alter-table columns create-table create-table-as create-view create-materialized-view drop-view drop-materialized-view + bulk-collect-into cross-join do-update-set drop-column drop-index drop-table from full-join group-by having insert-into join-by join lateral left-join limit offset on-conflict @@ -95,6 +96,26 @@ (from :bar) (order-by :quux))))))) +(deftest select-into-tests + (testing "SELECT INTO" + (is (= ["SELECT * INTO foo FROM bar"] + (sql/format {:select :* :into :foo :from :bar}))) + (is (= ["SELECT * INTO foo IN otherdb FROM bar"] + (sql/format {:select :* :into [:foo :otherdb] :from :bar}))) + (is (= ["SELECT * INTO foo FROM bar"] + (sql/format (-> (select '*) (h/into 'foo) (from 'bar))))) + (is (= ["SELECT * INTO foo IN otherdb FROM bar"] + (sql/format (-> (select :*) (h/into :foo :otherdb) (from :bar)))))) + (testing "SELECT BULK COLLECT INTO" + (is (= ["SELECT * BULK COLLECT INTO foo FROM bar"] + (sql/format {:select :* :bulk-collect-into :foo :from :bar}))) + (is (= ["SELECT * BULK COLLECT INTO foo LIMIT ? FROM bar" 100] + (sql/format {:select :* :bulk-collect-into [:foo 100] :from :bar}))) + (is (= ["SELECT * BULK COLLECT INTO foo FROM bar"] + (sql/format (-> (select :*) (bulk-collect-into :foo) (from :bar))))) + (is (= ["SELECT * BULK COLLECT INTO foo LIMIT ? FROM bar" 100] + (sql/format (-> (select :*) (bulk-collect-into :foo 100) (from :bar))))))) + (deftest from-expression-tests (testing "FROM can be a function invocation" (is (= ["SELECT foo, bar FROM F(?) AS x" 1] From 9f6393a2fdf2e7c5dce11abd8c8cb60146f72ffb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 13:46:47 -0800 Subject: [PATCH 195/254] Fix README now into is a helper function --- README.md | 19 ++++++++++++------- 1 file changed, 12 insertions(+), 7 deletions(-) diff --git a/README.md b/README.md index 65d1a95..9bcc550 100644 --- a/README.md +++ b/README.md @@ -30,10 +30,15 @@ Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty tr ## Usage ```clojure -(refer-clojure :exclude '[for group-by set update]) +(refer-clojure :exclude '[for group-by into partition-by set update]) (require '[honey.sql :as sql] - ;; caution: this overwrites for, group-by, set, and update - '[honey.sql.helpers :refer :all :as h]) + ;; caution: this overwrites several clojure.core fns: + ;; for, group-by, into, partition-by, set, and update + ;; you should generally only refer in the specific + ;; helpers that you want to use! + '[honey.sql.helpers :refer :all :as h] + ;; so we can still get at clojure.core functions: + '[clojure.core :as c]) ``` Everything is built on top of maps representing SQL queries: @@ -735,9 +740,9 @@ Or perhaps your database supports syntax like `a BETWIXT b AND c`, in which case [sql-c & params-c] (sql/format-expr c)] (-> [(str sql-a " " (sql/sql-kw op) " " sql-b " AND " sql-c)] - (into params-a) - (into params-b) - (into params-c))))) + (c/into params-a) + (c/into params-b) + (c/into params-c))))) ;; example usage: (-> (select :a) (where [:betwixt :a 1 10]) sql/format) => ["SELECT a WHERE a BETWIXT ? AND ?" 1 10] @@ -755,7 +760,7 @@ You can also register SQL clauses, specifying the keyword, the formatting functi (if (ident? x) (sql/format-expr x) (sql/format-dsl x))] - (into [(str (sql/sql-kw clause) " " sql)] params))) + (c/into [(str (sql/sql-kw clause) " " sql)] params))) :from) ; SELECT ... FOOBAR ... FROM ... ;; example usage: (sql/format {:select [:a :b] :foobar :baz}) From 7c21a403c23ce553f70e2a91d1fd0d8bd561e9eb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 15:35:47 -0800 Subject: [PATCH 196/254] Fixes #295 by documenting all helpers --- CHANGELOG.md | 3 +- src/honey/sql/helpers.cljc | 169 +++++++++++++++++++++++++++++++++++-- 2 files changed, 165 insertions(+), 7 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index ea35cc5..65f64b2 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -8,7 +8,8 @@ * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. * Add tests to confirm #299 does not affect v2. * Fix #297 by adding both `SELECT .. INTO ..` and `SELECT .. BULK COLLECT INTO ..`. - * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293). + * Fix #295 by adding docstrings to all helper functions (and adding an assert to ensure it stays that way as more are added in future). + * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293, but see #310 for recent additions not yet incorporated). * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. * Fix #284 by adding support for `LATERAL` (as special syntax, with a helper). * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 9eeb1db..dc7d265 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -2,7 +2,7 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." - (:refer-clojure :exclude [into update set group-by for partition-by]) + (:refer-clojure :exclude [for group-by into partition-by set update]) (:require [clojure.core :as c] [honey.sql])) @@ -12,6 +12,8 @@ (c/into (vec current) args)) (defn- and-merge + "Merge a single conjunction expression into an existing one. + This merges `AND` to avoid nesting." [current arg] (if-let [conj' (and (sequential? arg) (ident? (first arg)) @@ -30,6 +32,10 @@ (conj [:and] arg)))) (defn- and-merges + "Merge multiple conjunction expressions into an existing, + possibly empty, expression. This ensures AND expressions + are merged and that we do not end up with a single AND + or OR expression." [current args] (let [args (remove nil? args) result @@ -49,6 +55,7 @@ result))) (def ^:private special-merges + "Identify the conjunction merge clauses." {:where #'and-merges :having #'and-merges}) @@ -257,14 +264,27 @@ (generic :refresh-materialized-view views)) (defn nest + "A pseudo clause that exists purely to cause nesting + in parentheses. Should only be needed very rarely in + cases where HoneySQL doesn't do the right thing for + your specific database dialect. + + Wraps a single clause." + {:arglists '([clause])} [& args] (generic :nest args)) (defn with + "Accepts one or more CTE definitions. + + See the documentation for the `:with` clause." [& args] (generic :with args)) (defn with-recursive + "Accepts one or more CTE definitions. + + See the documentation for the `:with` clause." [& args] (generic :with-recursive args)) @@ -450,6 +470,8 @@ (generic :from tables)) (defn using + "Accepts similar arguments to `select` as part of + a SQL `USING` clause." [& args] (generic :using args)) @@ -470,30 +492,112 @@ (generic :join-by args)) (defn join + "Accepts one or more (INNER) JOIN expressions. Each + join expression is specified as a pair of arguments, + where the first one is the table name (or a pair of + table and alias) and the second one is the join + condition: + + (join :table [:= :foo.id :table.foo_id]) + (join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + INNER JOIN table ON foo.id = table.foo_id + INNER JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :join args)) (defn left-join + "Accepts one or more LEFT JOIN expressions. Each + join expression is specified as a pair of arguments, + where the first one is the table name (or a pair of + table and alias) and the second one is the join + condition: + + (left-join :table [:= :foo.id :table.foo_id]) + (left-join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + LEFT JOIN table ON foo.id = table.foo_id + LEFT JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :left-join args)) (defn right-join + "Accepts one or more RIGHT JOIN expressions. Each + join expression is specified as a pair of arguments, + where the first one is the table name (or a pair of + table and alias) and the second one is the join + condition: + + (right-join :table [:= :foo.id :table.foo_id]) + (right-join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + RIGHT JOIN table ON foo.id = table.foo_id + RIGHT JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :right-join args)) (defn inner-join + "An alternative name to `join`, this accepts one or + more INNER JOIN expressions. Each join expression + is specified as a pair of arguments, where the + first one is the table name (or a pair of table + and alias) and the second one is the join condition: + + (inner-join :table [:= :foo.id :table.foo_id]) + (inner-join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + INNER JOIN table ON foo.id = table.foo_id + INNER JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :inner-join args)) (defn outer-join + "Accepts one or more OUTER JOIN expressions. Each + join expression is specified as a pair of arguments, + where the first one is the table name (or a pair of + table and alias) and the second one is the join + condition: + + (outer-join :table [:= :foo.id :table.foo_id]) + (outer-join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + OUTER JOIN table ON foo.id = table.foo_id + OUTER JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :outer-join args)) (defn full-join + "Accepts one or more FULL JOIN expressions. Each + join expression is specified as a pair of arguments, + where the first one is the table name (or a pair of + table and alias) and the second one is the join + condition: + + (full-join :table [:= :foo.id :table.foo_id]) + (full-join [:table :t] [:= :foo.id :t.foo_id]) + + Produces: + INNER JOIN table ON foo.id = table.foo_id + INNER JOIN table AS t ON foo.id = t.foo_id" [& args] (generic :full-join args)) (defn cross-join + "Accepts one or more CROSS JOIN expressions. Each + cross join expression is specified as a table + name (or a pair of table and alias): + + (cross-join :table) + (cross-join [:table :t]) + + Produces: + CROSS JOIN table + CROSS JOIN table AS t" [& args] (generic :cross-join args)) @@ -509,6 +613,14 @@ (generic :where exprs)) (defn group-by + "Accepts one or more SQL expressions to group by. + + (group-by :foo :bar) + (group-by [:date :baz]) + + Produces: + GROUP BY foo, bar + GROUP BY DATE(baz)" [& args] (generic :group-by args)) @@ -524,19 +636,37 @@ (generic :having exprs)) (defn window + "Accepts a window name followed by a partition by clause." [& args] (generic :window args)) (defn partition-by + "Accepts one or more columns or SQL expressions to + partition by as part of a `WINDOW` expression." [& args] (generic :partition-by args)) (defn order-by + "Accepts one or more expressions to order by. + + An ordering expression may be a simple column name + which is assumed to be ordered `ASC`, or a pair of + an expression and a direction (`:asc` or `:desc`): + + (order-by :foo) + (order-by [:bar :desc]) + (order-by [[:date :baz] :asc]) + + Produces: + ORDER BY foo ASC + ORDER BY bar DESC + ORDER BY DATE(baz) ASC" [& args] (generic :order-by args)) (defn limit - "Specific to MySQL, accepts a single SQL expression: + "Specific to some databases (notabley MySQL), + accepts a single SQL expression: (limit 40) @@ -546,7 +676,9 @@ The two-argument syntax is not supported: use `offset` instead: - `LIMIT 20,10` is equivalent to `LIMIT 10 OFFSET 20`" + `LIMIT 20,10` is equivalent to `LIMIT 10 OFFSET 20` + + (-> (limit 10) (offset 20))" {:arglists '([limit])} [& args] (generic-1 :limit args)) @@ -574,10 +706,18 @@ (generic-1 :offset args)) (defn for + "Accepts a lock strength, optionally followed by one or + more table names, optionally followed by a qualifier." + {:arglists '([lock-strength table* qualifier*])} [& args] (generic-1 :for args)) (defn lock + "Intended for MySQL, this accepts a lock mode. + + It will accept the same type of syntax as `for` even + though MySQL's `lock` clause is less powerful." + {:arglists '([lock-mode])} [& args] (generic-1 :lock args)) @@ -599,6 +739,10 @@ (generic-1 :values args)) (defn on-conflict + "Accepts a single column name to detect conflicts + during an upsert, optionally followed by a `WHERE` + clause." + {:arglists '([column] [column where-clause])} [& args] (generic :on-conflict args)) @@ -615,10 +759,19 @@ (generic :do-nothing args)) (defn do-update-set + "Accepts one or more columns to update, or a hash map + of column/value pairs (like `set`), optionally followed + by a `WHERE` clause. Can also accept a single hash map + with a `:fields` entry specifying the columns to update + and a `:where` entry specifying the `WHERE` clause." + {:arglists '([field-where-map] [column-value-map] [column* opt-where-clause])} [& args] (generic :do-update-set args)) (defn on-duplicate-key-update + "MySQL's upsert facility. Accepts a hash map of + column/value pairs to be updated (like `set` does)." + {:arglists '([column-value-map])} [& args] (generic :on-duplicate-key-update args)) @@ -728,6 +881,10 @@ do-update-set)))))) #?(:clj - (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order - :composite :lateral :over :upsert)) - (clojure.core/set (map keyword (keys (ns-publics *ns*))))))) + (do + ;; ensure #295 stays true (all public functions have docstring): + (assert (empty? (->> (ns-publics *ns*) (vals) (filter (comp not :doc meta))))) + ;; ensure all public functions match clauses: + (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order + :composite :lateral :over :upsert)) + (clojure.core/set (map keyword (keys (ns-publics *ns*)))))))) From d76b2d82b103b6bd6ae093245b7d5155be427d4e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 13 Mar 2021 15:55:31 -0800 Subject: [PATCH 197/254] Prep for 2.0 Alpha 3 --- CHANGELOG.md | 6 +++--- README.md | 2 +- deps.edn | 2 +- doc/differences-from-1-x.md | 4 ++-- doc/getting-started.md | 6 +++--- pom.xml | 8 ++++---- 6 files changed, 14 insertions(+), 14 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 65f64b2..e7f572f 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,7 @@ # Changes -* 2.0.0-alpha3 in progress +* 2.0.0-alpha3 (for early testing; 2021-03-13) + * Change coordinates to `com.github.seancorfield/honeysql` (although new versions will continue to be deployed to `seancorfield/honeysql` for a while -- see the [Clojars Verified Group Names policy](https://github.com/clojars/clojars-web/wiki/Verified-Group-Names)). * Support much richer range of syntax on `CREATE`/`DROP` statements in general, including columns, `TABLESPACE`, `CASCADE`, `WITH [NO] DATA`, etc. * Fix #306 by supporting `CREATE TABLE .. AS ..`. * Fix #305 by supporting more complex join clauses. @@ -15,7 +16,6 @@ * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. - * 2.0.0-alpha2 (for early testing) * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. * Numerous small improvements have been made to clauses and helpers around insert/upsert. @@ -23,7 +23,7 @@ * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. * `honey.sql.helpers` -- provides a helper function for every piece of the DSL that is supported out-of-the-box. - * The coordinates for HoneySQL 2.0 are `seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.0 without any conflicts, making it easier to migrate piecemeal from 1.0 to 2.0. + * The coordinates for HoneySQL 2.0 are `com.github.seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.0 without any conflicts, making it easier to migrate piecemeal from 1.0 to 2.0. # HoneySQL pre-2.x Changes diff --git a/README.md b/README.md index 9bcc550..edab11b 100644 --- a/README.md +++ b/README.md @@ -12,7 +12,7 @@ This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINO Prerelease builds of the upcoming 2.x version of HoneySQL are available for testing: -[![Clojars Project](https://clojars.org/seancorfield/honeysql/latest-version.svg)](https://clojars.org/seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/seancorfield/honeysql?2.0.0-alpha2)](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha2) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-alpha3)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3) HoneySQL 2.x requires Clojure 1.9 or later. diff --git a/deps.edn b/deps.edn index 35a4240..9dce4ce 100644 --- a/deps.edn +++ b/deps.edn @@ -19,7 +19,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.13"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:replace-deps {seancorfield/depstar {:mvn/version "2.0.171"}} + :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.193"}} :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar" :sync-pom true}} :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 4f63c8d..e42c5d1 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -10,7 +10,7 @@ HoneySQL 1.x supported Clojure 1.7 and later. HoneySQL 2.x requires Clojure 1.9 ## Group, Artifact, and Namespaces -HoneySQL 2.x uses the group ID `seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). +HoneySQL 2.x uses the group ID `com.github.seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure will be available in `honey.specs` at some point (work in progress). @@ -46,7 +46,7 @@ Supported Clojure versions: 1.7 and later. ```clojure ;; in deps.edn: -seancorfield/honeysql {:mvn/version "2.x"} +com.github.seancorfield/honeysql {:mvn/version "2.x"} ;; in use: (ns my.project diff --git a/doc/getting-started.md b/doc/getting-started.md index 5455c3a..50a8741 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - seancorfield/honeysql {:mvn/version "2.0.0-alpha2"} + com.github.seancorfield/honeysql {:mvn/version "2.0.0-alpha3"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [seancorfield/honeysql "2.0.0-alpha2"] + [com.github.seancorfield/honeysql "2.0.0-alpha3"] ``` HoneySQL produces SQL statements but does not execute them. @@ -318,6 +318,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/seancorfield/honeysql/2.0.0-alpha2/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. diff --git a/pom.xml b/pom.xml index a268646..37bdc46 100644 --- a/pom.xml +++ b/pom.xml @@ -1,9 +1,9 @@ 4.0.0 - seancorfield + com.github.seancorfield honeysql - 2.0.0-alpha2 + 2.0.0-alpha3 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,13 +25,13 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-alpha2 + v2.0.0-alpha3 org.clojure clojure - 1.10.2 + 1.9.0 From fd84864279e9d2c3eb040ffd8893d106d28b3ffd Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Mar 2021 14:48:28 -0700 Subject: [PATCH 198/254] Fixes #161 by adding :raw clause support --- CHANGELOG.md | 3 +++ doc/clause-reference.md | 9 +++++++++ doc/special-syntax.md | 4 +++- src/honey/sql.cljc | 31 +++++++++++++++++-------------- src/honey/sql/helpers.cljc | 14 ++------------ 5 files changed, 34 insertions(+), 27 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index e7f572f..bf3d474 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.next in progress + * Fix #161 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). + * 2.0.0-alpha3 (for early testing; 2021-03-13) * Change coordinates to `com.github.seancorfield/honeysql` (although new versions will continue to be deployed to `seancorfield/honeysql` for a while -- see the [Clojars Verified Group Names policy](https://github.com/clojars/clojars-web/wiki/Verified-Group-Names)). * Support much richer range of syntax on `CREATE`/`DROP` statements in general, including columns, `TABLESPACE`, `CASCADE`, `WITH [NO] DATA`, etc. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 21a6047..e4312d4 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -154,6 +154,15 @@ needed and it is mostly present to provide the same functionality for clauses that `[:nest ..]` provides for expressions. +## raw + +This is pseudo-syntax that lets you insert a complete +SQL clause as a string, if HoneySQL doesn't support +some exotic SQL construct. It should rarely be +needed and it is mostly present to provide the same +functionality for clauses that `[:raw ..]` provides +for expressions (which usage is likely to be more common). + ## with, with-recursive These provide CTE support for SQL Server. The argument to diff --git a/doc/special-syntax.md b/doc/special-syntax.md index 98f8c2e..46d4e07 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -129,7 +129,7 @@ level of parentheses around it: ;;=> ["WHERE (x = ?)" 42] ``` -`nest` is also supported as a SQL clause for the same reason. +`:nest` is also supported as a SQL clause for the same reason. ## not @@ -202,6 +202,8 @@ parameters from them: ;;=> ["SELECT a, @var := ?" "foo"] ``` +`:raw` is also supported as a SQL clause for the same reason. + ## Column Descriptors There are three types of descriptors that vary diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index a6cadb4..57d5fbe 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -44,7 +44,7 @@ :drop-table :drop-view :drop-materialized-view :drop-extension :refresh-materialized-view ;; then SQL clauses in priority order: - :nest :with :with-recursive :intersect :union :union-all :except :except-all + :raw :nest :with :with-recursive :intersect :union :union-all :except :except-all :select :select-distinct :select-distinct-on :select-top :select-distinct-top :into :bulk-collect-into :insert-into :update :delete :delete-from :truncate @@ -716,6 +716,20 @@ (defn- format-rename-item [k [x y]] [(str (sql-kw k) " " (format-entity x) " TO " (format-entity y))]) +(defn- raw-render [_ [s]] + (if (sequential? s) + (let [[sqls params] + (reduce (fn [[sqls params] s] + (if (sequential? s) + (let [[sql & params'] (format-expr s)] + [(conj sqls sql) + (into params params')]) + [(conj sqls s) params])) + [[] []] + s)] + (into [(str/join sqls)] params)) + [s])) + (def ^:private base-clause-order "The (base) order for known clauses. Can have items added and removed. @@ -751,6 +765,7 @@ :drop-view #'format-drop-items :drop-materialized-view #'format-drop-items :refresh-materialized-view (fn [_ x] (format-create :refresh :materialized-view x nil)) + :raw #'raw-render :nest (fn [_ x] (format-expr x)) :with #'format-with :with-recursive #'format-with @@ -1049,19 +1064,7 @@ [(sqlize-value (param-value k))] ["?" (->param k)])) :raw - (fn [_ [s]] - (if (sequential? s) - (let [[sqls params] - (reduce (fn [[sqls params] s] - (if (sequential? s) - (let [[sql & params'] (format-expr s)] - [(conj sqls sql) - (into params params')]) - [(conj sqls s) params])) - [[] []] - s)] - (into [(str/join sqls)] params)) - [s]))})) + #'raw-render})) (defn format-expr "Given a data structure that represents a SQL expression and a hash diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index dc7d265..8f9b4d4 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -263,17 +263,6 @@ [& views] (generic :refresh-materialized-view views)) -(defn nest - "A pseudo clause that exists purely to cause nesting - in parentheses. Should only be needed very rarely in - cases where HoneySQL doesn't do the right thing for - your specific database dialect. - - Wraps a single clause." - {:arglists '([clause])} - [& args] - (generic :nest args)) - (defn with "Accepts one or more CTE definitions. @@ -887,4 +876,5 @@ ;; ensure all public functions match clauses: (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order :composite :lateral :over :upsert)) - (clojure.core/set (map keyword (keys (ns-publics *ns*)))))))) + (clojure.core/set (conj (map keyword (keys (ns-publics *ns*))) + :nest :raw)))))) From 9672ed3704ec2e37babf7b8782d0aa448c06ce0a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Mar 2021 15:26:22 -0700 Subject: [PATCH 199/254] Fixes #312 (properly this time) --- src/honey/sql.cljc | 7 ++++--- 1 file changed, 4 insertions(+), 3 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 57d5fbe..5ace1ee 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -716,7 +716,7 @@ (defn- format-rename-item [k [x y]] [(str (sql-kw k) " " (format-entity x) " TO " (format-entity y))]) -(defn- raw-render [_ [s]] +(defn- raw-render [s] (if (sequential? s) (let [[sqls params] (reduce (fn [[sqls params] s] @@ -765,7 +765,7 @@ :drop-view #'format-drop-items :drop-materialized-view #'format-drop-items :refresh-materialized-view (fn [_ x] (format-create :refresh :materialized-view x nil)) - :raw #'raw-render + :raw (fn [_ x] (raw-render x)) :nest (fn [_ x] (format-expr x)) :with #'format-with :with-recursive #'format-with @@ -1064,7 +1064,8 @@ [(sqlize-value (param-value k))] ["?" (->param k)])) :raw - #'raw-render})) + (fn [_ [xs]] + (raw-render xs))})) (defn format-expr "Given a data structure that represents a SQL expression and a hash From 73c2062d6e7b5313de0e77d335ff00ea8fe1bbae Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Mar 2021 16:45:26 -0700 Subject: [PATCH 200/254] Investigation of string-as-entity behavior This is something that should be updated in the docs. --- src/honey/sql.cljc | 6 ++++++ 1 file changed, 6 insertions(+) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5ace1ee..573d051 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -168,6 +168,12 @@ t (str (q t) ".")))) +(comment + (for [v [:foo-bar 'foo-bar "foo-bar"] a [true false] d [true false]] + (binding [*dialect* (:mysql dialects)] + (format-entity v :aliased a :drop-ns d))) + .) + (defn- param-value [k] (if (contains? *params* k) (get *params* k) From 13d62b4ac1fc631b05582e960005ed04dca8411e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Mar 2021 16:54:13 -0700 Subject: [PATCH 201/254] Also show quoting/not-quoting and table.col forms --- src/honey/sql.cljc | 6 ++++-- 1 file changed, 4 insertions(+), 2 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 573d051..2b64011 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -169,8 +169,10 @@ (str (q t) ".")))) (comment - (for [v [:foo-bar 'foo-bar "foo-bar"] a [true false] d [true false]] - (binding [*dialect* (:mysql dialects)] + (for [v [:foo-bar 'foo-bar "foo-bar" + :f-o.bar 'f-o.bar "f-o.bar"] + a [true false] d [true false] q [true false]] + (binding [*dialect* (:mysql dialects) *quoted* q] (format-entity v :aliased a :drop-ns d))) .) From fde22f6bc08cb4f7f45b8f60e222781d7dd513ce Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 15 Mar 2021 16:55:51 -0700 Subject: [PATCH 202/254] Correct issue # in change log --- CHANGELOG.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index bf3d474..6297ab1 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,7 +1,7 @@ # Changes * 2.0.next in progress - * Fix #161 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). + * Fix #312 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). * 2.0.0-alpha3 (for early testing; 2021-03-13) * Change coordinates to `com.github.seancorfield/honeysql` (although new versions will continue to be deployed to `seancorfield/honeysql` for a while -- see the [Clojars Verified Group Names policy](https://github.com/clojars/clojars-web/wiki/Verified-Group-Names)). From 337d2c7f5d2910075cdf9a91411a562983431e9c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 21 Mar 2021 11:55:47 -0700 Subject: [PATCH 203/254] Minor library version updates --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index 9dce4ce..26a900c 100644 --- a/deps.edn +++ b/deps.edn @@ -19,7 +19,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.13"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.193"}} + :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.206"}} :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar" :sync-pom true}} :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} From 230aa7088a3344adb8da3a34c10e8614ae5f1f97 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 21 Mar 2021 12:07:08 -0700 Subject: [PATCH 204/254] Minor library updates --- .github/workflows/test.yml | 4 ++-- deps.edn | 4 ++-- 2 files changed, 4 insertions(+), 4 deletions(-) diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index d29c6e3..be44dec 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -7,7 +7,7 @@ jobs: runs-on: ubuntu-latest strategy: matrix: - java: [ '8', '11', '14' ] + java: [ '8', '11', '14', '15', '16', '17-ea' ] steps: - uses: actions/checkout@v2 - name: Setup Java @@ -17,7 +17,7 @@ jobs: - name: Setup Clojure uses: DeLaGuardo/setup-clojure@master with: - tools-deps: '1.10.2.774' + tools-deps: '1.10.3.814' - name: Run Tests run: sh run-tests.sh all - name: Check cljdoc.edn diff --git a/deps.edn b/deps.edn index 26a900c..b9cb73b 100644 --- a/deps.edn +++ b/deps.edn @@ -4,7 +4,7 @@ :aliases {:1.9 {:override-deps {org.clojure/clojure {:mvn/version "1.9.0"}}} :1.10 {:override-deps {org.clojure/clojure {:mvn/version "1.10.3"}}} - :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.0-master-SNAPSHOT"}}} + :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.1-master-SNAPSHOT"}}} :test {:extra-paths ["test"]} :runner {:extra-deps {com.cognitect/test-runner @@ -17,7 +17,7 @@ :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} - :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.13"}} + :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.14"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.206"}} :exec-fn hf.depstar/jar From 24b87ebd69e756d910d38bece954f3e1d2de864d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 21 Mar 2021 12:23:42 -0700 Subject: [PATCH 205/254] Use Clojure 1.10 for Eastwood 0.3.14 --- run-tests.sh | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/run-tests.sh b/run-tests.sh index 9164ed7..7017ade 100755 --- a/run-tests.sh +++ b/run-tests.sh @@ -1,7 +1,7 @@ #!/bin/sh echo ==== Test README.md ==== && clojure -M:readme && \ - echo ==== Lint Source ==== && clojure -M:eastwood && \ + echo ==== Lint Source ==== && clojure -M:1.10:eastwood && \ echo ==== Test ClojureScript ==== && clojure -M:test:cljs-runner if test $? -eq 0 From b010f9158679228ba949e7a858746cd852d3b78b Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 1 Apr 2021 12:28:13 -0700 Subject: [PATCH 206/254] Update Eastwood; run it on Clojure 1.9 --- deps.edn | 2 +- run-tests.sh | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/deps.edn b/deps.edn index b9cb73b..1b1e640 100644 --- a/deps.edn +++ b/deps.edn @@ -17,7 +17,7 @@ :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} - :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.3.14"}} + :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.4.0"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.206"}} :exec-fn hf.depstar/jar diff --git a/run-tests.sh b/run-tests.sh index 7017ade..9164ed7 100755 --- a/run-tests.sh +++ b/run-tests.sh @@ -1,7 +1,7 @@ #!/bin/sh echo ==== Test README.md ==== && clojure -M:readme && \ - echo ==== Lint Source ==== && clojure -M:1.10:eastwood && \ + echo ==== Lint Source ==== && clojure -M:eastwood && \ echo ==== Test ClojureScript ==== && clojure -M:test:cljs-runner if test $? -eq 0 From 06f25ed2e3f96abce4920feca6034f954e138277 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 1 Apr 2021 12:50:09 -0700 Subject: [PATCH 207/254] Fixes #317 by dropping qualifier in :set clause --- CHANGELOG.md | 1 + src/honey/sql.cljc | 2 +- test/honey/sql_test.cljc | 40 ++++++++++++++++++++++++++++++++-------- 3 files changed, 34 insertions(+), 9 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 6297ab1..0d335a2 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,7 @@ # Changes * 2.0.next in progress + * Fix #317 by dropping qualifiers in `:set` clauses (just like we do with `:insert` columns). Note that you can still use explicit _dotted_ names if you want table qualification. * Fix #312 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). * 2.0.0-alpha3 (for early testing; 2021-03-13) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 2b64011..f79ef19 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -559,7 +559,7 @@ (let [[sqls params] (reduce-kv (fn [[sql params] v e] (let [[sql' & params'] (format-expr e)] - [(conj sql (str (format-entity v) " = " sql')) + [(conj sql (str (format-entity v {:drop-ns true}) " = " sql')) (if params' (into params params') params)])) [[] []] xs)] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index dfdb7e8..e774603 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -337,17 +337,41 @@ #_{:parameterizer :mysql-fill}) ["WHERE (foo = ?) AND (bar = ?) AND (quux = ?)" "foo" "bar" "quux"])))) -(deftest set-before-from ; issue 235 +(deftest set-before-from + ;; issue 235 (is (= ["UPDATE \"films\" \"f\" SET \"kind\" = \"c\".\"test\" FROM (SELECT \"b\".\"test\" FROM \"bar\" AS \"b\" WHERE \"b\".\"id\" = ?) AS \"c\" WHERE \"f\".\"kind\" = ?" 1 "drama"] (-> - {:update [:films :f] - :set {:kind :c.test} - :from [[{:select [:b.test] - :from [[:bar :b]] - :where [:= :b.id 1]} :c]] - :where [:= :f.kind "drama"]} - (format {:quoted true}))))) + {:update [:films :f] + :set {:kind :c.test} + :from [[{:select [:b.test] + :from [[:bar :b]] + :where [:= :b.id 1]} :c]] + :where [:= :f.kind "drama"]} + (format {:quoted true})))) + ;; issue 317 + (is (= + ["UPDATE \"films\" \"f\" SET \"kind\" = \"c\".\"test\" FROM (SELECT \"b\".\"test\" FROM \"bar\" AS \"b\" WHERE \"b\".\"id\" = ?) AS \"c\" WHERE \"f\".\"kind\" = ?" 1 "drama"] + (-> + {:update [:films :f] + ;; drop ns in set clause... + :set {:f/kind :c.test} + :from [[{:select [:b.test] + :from [[:bar :b]] + :where [:= :b.id 1]} :c]] + :where [:= :f.kind "drama"]} + (format {:quoted true})))) + (is (= + ["UPDATE \"films\" \"f\" SET \"f\".\"kind\" = \"c\".\"test\" FROM (SELECT \"b\".\"test\" FROM \"bar\" AS \"b\" WHERE \"b\".\"id\" = ?) AS \"c\" WHERE \"f\".\"kind\" = ?" 1 "drama"] + (-> + {:update [:films :f] + ;; ...but keep literal dotted name + :set {:f.kind :c.test} + :from [[{:select [:b.test] + :from [[:bar :b]] + :where [:= :b.id 1]} :c]] + :where [:= :f.kind "drama"]} + (format {:quoted true}))))) (deftest set-after-join (is (= From dbecb152a164742ff4c56dca270598f094dbd5be Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 8 Apr 2021 23:06:07 -0700 Subject: [PATCH 208/254] Documentation updates and clarifications This adds placeholders for reference documentation. --- doc/cljdoc.edn | 1 + doc/differences-from-1-x.md | 22 ++++++++++++++-------- doc/general-reference.md | 28 ++++++++++++++++++++++++++++ doc/getting-started.md | 24 +++++++++++++----------- 4 files changed, 56 insertions(+), 19 deletions(-) create mode 100644 doc/general-reference.md diff --git a/doc/cljdoc.edn b/doc/cljdoc.edn index 024ed98..366b459 100644 --- a/doc/cljdoc.edn +++ b/doc/cljdoc.edn @@ -2,6 +2,7 @@ [["Readme" {:file "README.md"}] ["Changes" {:file "CHANGELOG.md"}] ["Getting Started" {:file "doc/getting-started.md"} + ["General Reference" {:file "doc/general-reference.md"}] ["SQL Clause Reference" {:file "doc/clause-reference.md"}] ["SQL Operator Reference" {:file "doc/operator-reference.md"}] ["SQL 'Special Syntax'" {:file "doc/special-syntax.md"}] diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index e42c5d1..bb8cd50 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -10,7 +10,7 @@ HoneySQL 1.x supported Clojure 1.7 and later. HoneySQL 2.x requires Clojure 1.9 ## Group, Artifact, and Namespaces -HoneySQL 2.x uses the group ID `com.github.seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/). +HoneySQL 2.x uses the group ID `com.github.seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/); also Clojars [Verified Group Names policy](https://github.com/clojars/clojars-web/wiki/Verified-Group-Names). In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure will be available in `honey.specs` at some point (work in progress). @@ -80,7 +80,7 @@ You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialec As noted above, the variadic options for `format` have been replaced by a single hash map as the optional second argument to `format`. -The `:quoting ` option has superseded by the new dialect machinery and a new `:quoted` option that turns quoting on or off. You either use `:dialect ` instead or set a default dialect (via `set-dialect!`) and then use `{:quoted true}` in `format` calls where you want quoting. +The `:quoting ` option has superseded by the new dialect machinery and a new `:quoted` option that turns quoting on or off. You either use `:dialect ` instead or set a default dialect (via `set-dialect!`) and then use `:quoted true` in `format` calls where you want quoting. Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. @@ -105,11 +105,14 @@ The following new syntax has been added: * `:cast` -- `[:cast expr :type]` => `CAST( expr AS type )`, * `:composite` -- explicit syntax to produce a comma-separated list of expressions, wrapped in parentheses, * `:default` -- for `DEFAULT` values (in inserts) and for declaring column defaults in table definitions, +* `:escape` -- used to wrap a regular expression so that non-standard escape characters can be provided, * `:inline` -- used as a function to replace the `sql/inline` / `#sql/inline` machinery, -* `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`. +* `:interval` -- used as a function to support `INTERVAL `, e.g., `[:interval 30 :days]`, +* `:lateral` -- used to wrap a statement or expression, to provide a `LATERAL` join, * `:lift` -- used as a function to prevent interpretation of a Clojure data structure as DSL syntax (e.g., when passing a vector or hash map as a parameter value) -- this should mostly be a replacement for `honeysql.format/value`, * `:nest` -- used as a function to add an extra level of nesting (parentheses) around an expression, * `:not` -- this is now explicit syntax, +* `:over` -- the function-like part of a T-SQL window clause, * `:param` -- used as a function to replace the `sql/param` / `#sql/param` machinery, * `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the v1 behavior but should be more flexible, since you can now embed `:inline`, `:param`, and `:lift` inside a `:raw` expression. @@ -117,8 +120,10 @@ The following new syntax has been added: Several additional pieces of syntax have also been added to support column definitions in `CREATE TABLE` clauses, now that v2 supports DDL statement -construction: `:constraint`, `:foreign-key`, `:index`, `:primary-key`, -`:references`, `:unique`, and -- as noted above -- `:default`. +construction: + +* `:constraint`, `:default`, `:foreign-key`, `:index`, `:primary-key`, `:references`, `:unique`, +* `:entity` -- used to force an expression to be rendered as a SQL entity (instead of a SQL keyword). ### select and function calls @@ -174,6 +179,7 @@ And, finally, you can register new operators that will be recognized in expressi The `honey.sql.helpers` namespace includes a helper function that corresponds to every supported piece of the data DSL understood by HoneySQL (v1 only had a limited set of helper functions). Unlike v1 helpers which sometimes had both a regular helper and a `merge-` helper, v2 helpers will all merge clauses by default (if that makes sense for the underlying DSL): use `:dissoc` if you want to force an overwrite. The only helpers that have non-merging behavior are: -* `intersect`, `union`, `union-all`, `except`, and `except-all` which always wrap around their arguments, -* `delete`, `set`, `limit`, `offset`, `for`, and `values` which overwrite, rather than merge, -* `composite` which is a convenience for the `:composite` syntax mentioned above: `(composite :a :b)` is the same as `[:composite :a :b]` which produces `(a, b)`. +* The SQL set operations `intersect`, `union`, `union-all`, `except`, and `except-all` which always wrap around their arguments, +* The SQL clauses `delete`, `fetch`, `for`, `limit`, `lock`, `offset`, `on-constraint`, `set`, `truncate`, `update`, and `values` which overwrite, rather than merge, +* The DDL helpers `drop-column`, `drop-index`, `rename-table`, and `with-data`, +* The function helper `composite` which is a convenience for the `:composite` syntax mentioned above: `(composite :a :b)` is the same as `[:composite :a :b]` which produces `(a, b)`. diff --git a/doc/general-reference.md b/doc/general-reference.md new file mode 100644 index 0000000..c1c2cf2 --- /dev/null +++ b/doc/general-reference.md @@ -0,0 +1,28 @@ +# General Reference Documentation + +This section provides more details about specific behavior in HoneySQL and +how to generate certain SQL constructs. + +## SQL Entity Generation + +See #313 + +## Tuples and Composite Values + +See #314 + +## Other Sections Will Be Added! + +## Other Reference Documentation + +The full list of supported SQL clauses is documented in the +[Clause Reference](clause-reference.md). The full list +of operators supported (as prefix-form "functions") is +documented in the [Operator Reference](operator-reference.md) +section. The full list +of "special syntax" functions is documented in the +[Special Syntax](special-syntax.md) section. The best +documentation for the helper functions is in the +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3/api/honey.sql.helpers) namespace. +If you're migrating to HoneySQL 2.0, this [overview of differences +between 1.0 and 2.0](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index 50a8741..05f4326 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -26,7 +26,7 @@ To execute SQL statements, you will also need a JDBC wrapper like SQL statements are represented as hash maps, with keys that represent clauses in SQL. SQL expressions are generally -represented as vectors, where the first element identifies +represented as sequences, where the first element identifies the function or operator and the remaining elements are the arguments or operands. @@ -50,10 +50,10 @@ or symbols, are treated as positional parameters and replaced by `?` in the SQL string and lifted out into the vector that is returned from `format`. -Most clauses expect a vector as their value, containing +Most clauses expect a sequence as their value, containing either a list of SQL entities or the representation of a SQL expression. Some clauses accept a single SQL entity. A few -accept a most specialized form (such as `:set` accepting a +accept a more specialized form (such as `:set` accepting a hash map of SQL entities and SQL expressions). A SQL entity can be a simple keyword (or symbol) or a pair @@ -97,7 +97,7 @@ the table name, i.e., `:foo/bar` instead of `:foo.bar`: ## SQL Expressions In addition to using hash maps to describe SQL clauses, -HoneySQL uses vectors to describe SQL expressions. Any +HoneySQL uses sequences to describe SQL expressions. Any sequence that begins with a keyword (or symbol) is considered to be a kind of function invocation. Certain "functions" are considered to be "special syntax" and have custom rendering. @@ -168,7 +168,7 @@ call as the `:params` key of the options hash map. ## Functional Helpers -In addition to the hash map (and vectors) approach of building +In addition to the hash map (and sequences) approach of building SQL queries with raw Clojure data structures, a namespace full of helper functions is also available. These functions are generally variadic and threadable: @@ -188,9 +188,9 @@ generally variadic and threadable: There is a helper function for every single clause that HoneySQL supports out of the box. In addition, there are helpers for -`composite` and `over` that make it easier to construct those -parts of the SQL DSL (examples of the former appear in the [README](README.md), -examples of the latter appear in the [Clause Reference](docs/clause-reference.md)) +`composite`, `lateral`, `over`, and `upsert` that make it easier to construct those +parts of the SQL DSL (examples of `composite` appear in the [README](README.md), +examples of `over` appear in the [Clause Reference](docs/clause-reference.md)) In addition to being variadic -- which often lets you omit one level of `[`..`]` -- the helper functions merge clauses, which @@ -225,7 +225,7 @@ can rely on using keywords in `dissoc`. The following helpers shadow functions in `clojure.core` so you need to consider this when referring symbols in from the -`honey.sql.helpers` namespace: `for`, `group-by`, `partition-by`, +`honey.sql.helpers` namespace: `for`, `group-by`, `into`, `partition-by`, `set`, and `update`. ## DDL Statements @@ -234,7 +234,7 @@ HoneySQL 1.x did not support any DDL statements. It was fairly common for people to use the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) to get DDL support, even if they didn't need the PostgreSQL-specific extensions. That library does not work with HoneySQL 2.x but all -of the functionality from it has been incorporated +of the functionality from it (up to 0.3.104) has been incorporated into HoneySQL now and is described in the [PostgreSQL](postgresql.md) section (because that covers all of the things that the nilenso library supported and much of it was PostgreSQL-specific!). @@ -288,7 +288,7 @@ specify a dialect in the `format` call, you can specify Out of the box, as part of the extended ANSI SQL support, HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md). -> Note: the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library out of the box! +> Note: the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library (up to 0.3.104) out of the box! ## Format Options @@ -319,5 +319,7 @@ of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the [honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3/api/honey.sql.helpers) namespace. +More detail about certain core HoneySQL functionality can be found in the +[Reference documentation](general-reference.md). If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. From cfb001e2f58ac72c1d923eb7bbb9b66d9924f3e9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 12:43:09 -0700 Subject: [PATCH 209/254] Complete the clause documentation! --- doc/clause-reference.md | 85 ++++++++++++++++++++++++++++++++++++++--- 1 file changed, 80 insertions(+), 5 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index e4312d4..e94a87b 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -11,6 +11,12 @@ a space (e.g., `:left-join` is formatted as `LEFT JOIN`). Except as noted, these clauses apply to all the SQL dialects that HoneySQL supports. +DDL clauses are listed first, followed by SQL clauses. + +# DDL Clauses + +HoneySQL supports the following DDL clauses as a data DSL. + ## alter-table, add-column, drop-column, modify-column, rename-column `:alter-table` can accept either a single table name or @@ -52,7 +58,7 @@ expressions); `:drop-column` accepts a single column name, and `:rename-column` accepts a sequence with two column names: the "from" and the "to" names. -## add-index, drop-index +### add-index, drop-index Used with `:alter-table`, `:add-index` accepts a single (function) expression @@ -70,7 +76,7 @@ user=> (sql/format {:alter-table :fruit :drop-index :look}) ["ALTER TABLE fruit DROP INDEX look"] ``` -## rename-table +### rename-table Used with `:alter-table`, `:rename-table` accepts a single table name: @@ -116,13 +122,50 @@ in the example above, but allow things like `CHECK` for a constraint, `FOREIGN KEY` (with a column name), `REFERENCES` (with a pair of column names). See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. -## create-table-as, create-view, and others +## create-table-as + +`:create-table-as` can accept a single table name or a sequence +that starts with a table name, optionally followed by +a flag indicating the creation should be conditional +(`:if-not-exists` or the symbol `if-not-exists`), +optionally followed by a `{:columns ..}` clause to specify +the columns to use in the created table, optionally followed +by special syntax to specify `TABLESPACE` etc. + +For example: + +```clojure +user=> (sql/format {:create-table-as [:metro :if-not-exists + {:columns [:foo :bar :baz]} + [:tablespace [:entity :quux]]], + :select [:*], + :from [:cities], + :where [:= :metroflag "y"], + :with-data false} + {:pretty true}) +[" +CREATE TABLE IF NOT EXISTS metro (foo, bar, baz) TABLESPACE quux AS +SELECT * +FROM cities +WHERE metroflag = ? +WITH NO DATA +" "y"] +``` + +Without the `{:columns ..}` clause, the table will be created +based on the columns in the query that follows. ## create-extension +`:create-extension` can accept a single extension name or a pair +of the extension name, followed by +a flag indicating the creation should be conditional +(`:if-not-exists` or the symbol `if-not-exists`). +See the [PostgreSQL](postgresql.md) section for examples. + ## create-view, create-materialized-view -`:create-view` accepts a single view name: +`:create-view` and `:create-materialized-view` both accept a single view name: ```clojure user=> (sql/format {:create-view :products @@ -146,6 +189,14 @@ user=> (sql/format {:drop-table [:foo :bar]}) ["DROP TABLE foo, bar"] ``` +# SQL Pseudo-Syntax Clauses + +The following data DSL clauses are supported to let +you modify how SQL clauses are generated, if the default +generation is incorrect or unsupported. + +See also the [Extending HoneySQL](extending-honeysql.md) section. + ## nest This is pseudo-syntax that lets you wrap a substatement @@ -163,6 +214,12 @@ needed and it is mostly present to provide the same functionality for clauses that `[:raw ..]` provides for expressions (which usage is likely to be more common). +# SQL Clauses + +HoneySQL supports the following SQL clauses as a data DSL. +These are listed in precedence order (i.e., matching the +order they would appear in a valid SQL statement). + ## with, with-recursive These provide CTE support for SQL Server. The argument to @@ -243,6 +300,24 @@ or `SELECT .. BULK COLLECT INTO ..`. ## select-top, select-distinct-top +`:select-top` and `:select-distinct-top` are variants of `:select` +and `:select-distinct`, respectively, that provide support for +MS SQL Server's `TOP` modifier on a `SELECT` statement. + +They accept a sequence that starts with an expression to be +used as the `TOP` limit value, followed by SQL entities as +supported by `:select` above. + +The `TOP` expression can either be a general SQL expression +or a sequence whose first element is a general SQL expression, +followed by qualifiers for `:percent` and/or `:with-ties` (or +the symbols `percent` and/or `with-ties`). + +```clojure +user=> (sql/format {:select-top [[10 :percent :with-ties] :foo :baz] :from :bar :order-by [:quux]}) +["SELECT TOP(?) PERCENT WITH TIES foo, baz FROM bar ORDER BY quux ASC" 10] +``` + ## select-distinct-on Similar to `:select-distinct` above but the first element @@ -605,7 +680,7 @@ user=> (sql/format {:select [:*] :from :table Some databases, including MySQL, support `:limit` and `:offset` for paginated queries, other databases support `:offset` and -`fetch` for that (which is ANSI-compliant and should be +`:fetch` for that (which is ANSI-compliant and should be preferred if your database supports it). All three expect a single SQL expression: From b321df25d95f3ca92ab5692127f91b2f04b53981 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 12:50:21 -0700 Subject: [PATCH 210/254] Add note about SQL Server TOP --- doc/differences-from-1-x.md | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index bb8cd50..75f7352 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -142,7 +142,8 @@ On a related note, `sql/call` has been removed because it should never be needed HoneySQL 1.x provided a `:modifiers` clause (and a `modifiers`) helper as a way to "modify" a `SELECT` to be `DISTINCT`. nilenso/honeysql-helpers extended that to support `:distinct-on` a group of columns. In HoneySQL 2.x, you use `:select-distinct` and `:select-distinct-on` -(and their associated helpers) for that instead. +(and their associated helpers) for that instead. MS SQL Server's `TOP` modifier is also +supported via `:select-top` and `:select-distinct-top`. ### set vs sset, set0, set1 From af382708e5494aaf6ed4d03c97e419aa60081700 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 15:58:56 -0700 Subject: [PATCH 211/254] Fixes #319 by making register-clause! idempotent Technically, it removes any instance of the clause from the ordering before it attempts to add it back in, allowing you to correct the order if you got it wrong. --- CHANGELOG.md | 1 + src/honey/sql.cljc | 37 ++++++++++++++++++++----------------- test/honey/sql_test.cljc | 8 ++++++++ 3 files changed, 29 insertions(+), 17 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 0d335a2..8f8fa6d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,7 @@ # Changes * 2.0.next in progress + * Fix #319 by ensuring `register-clause!` is idempotent. * Fix #317 by dropping qualifiers in `:set` clauses (just like we do with `:insert` columns). Note that you can still use explicit _dotted_ names if you want table qualification. * Fix #312 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index f79ef19..4e58ee6 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -60,29 +60,32 @@ :with-data]) (defn- add-clause-before - "Low-level helper just to insert a new clause." + "Low-level helper just to insert a new clause. + + If the clause is already in the list, remove it." [order clause before] - (if before - (do - (when-not (contains? (set order) before) - (throw (ex-info (str "Unrecognized clause: " before) - {:known-clauses order}))) - (reduce (fn [v k] - (if (= k before) - (conj v clause k) - (conj v k))) - [] - order)) - (conj order clause))) + (let [clauses (set order) + order (if (contains? clauses clause) + (filterv #(not= % clause) order) + order)] + (if before + (do + (when-not (contains? clauses before) + (throw (ex-info (str "Unrecognized clause: " before) + {:known-clauses order}))) + (reduce (fn [v k] + (if (= k before) + (conj v clause k) + (conj v k))) + [] + order)) + (conj order clause)))) (def ^:private dialects {:ansi {:quote #(str \" % \")} :sqlserver {:quote #(str \[ % \])} :mysql {:quote #(str \` % \`) - :clause-order-fn (fn [order] - ;; MySQL :set has different priority - (-> (filterv (complement #{:set}) order) - (add-clause-before :set :where)))} + :clause-order-fn #(add-clause-before % :set :where)} :oracle {:quote #(str \" % \") :as false}}) ; should become defonce diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index e774603..1ccafa1 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -623,3 +623,11 @@ ORDER BY id = ? DESC (format {:insert-into :table :values [{:name name :enabled enabled}]}))))) + +(deftest issue-319-test + (testing "that registering a clause is idempotent" + (is (= ["FOO"] + (do + (sut/register-clause! :foo (constantly ["FOO"]) nil) + (sut/register-clause! :foo (constantly ["FOO"]) nil) + (format {:foo []})))))) From 106b19bcf6e4d2910c91ee46a021e54073ad7375 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 16:31:16 -0700 Subject: [PATCH 212/254] Add clause-order to see current clause order This should help when folks are figuing out `register-clause!` calls. --- doc/extending-honeysql.md | 10 ++++------ src/honey/sql.cljc | 12 +++++++++++- 2 files changed, 15 insertions(+), 7 deletions(-) diff --git a/doc/extending-honeysql.md b/doc/extending-honeysql.md index 69dafe9..ed734e6 100644 --- a/doc/extending-honeysql.md +++ b/doc/extending-honeysql.md @@ -33,12 +33,10 @@ The third argument to `register-clause!` allows you to insert your new clause formatter so that clauses are formatted in the correct order for your SQL dialect. For example, `:select` comes before `:from` which comes -before `:where`. This is the most implementation-specific -part of extending HoneySQL because you'll need to look at -the (private) Var `default-clause-order` in `honey.sql` -for guidance. _[I plan to add a section in the documentation -somewhere that lists built-in clauses in order which this -can link to...]_ +before `:where`. You can call `clause-order` to see what the +current ordering of clauses is. + +> Note: if you call `register-clause!` more than once for the same clause, the last call "wins". This allows you to correct an incorrect clause order insertion by simply calling `register-clause!` again with a different third argument. ## Registering a New Operator diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4e58ee6..baf0ce3 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -1205,6 +1205,14 @@ (when-let [f (:clause-order-fn @default-dialect)] (reset! current-clause-order (f @base-clause-order)))) +(defn clause-order + "Return the current order that known clauses will be applied when + formatting a data structure into SQL. This may be useful when you are + figuring out the `before` argument of `register-clause!` as well as + for debugging new clauses you have registered." + [] + @current-clause-order) + (defn register-clause! "Register a new clause formatter. If `before` is `nil`, the clause is added to the end of the list of known clauses, otherwise it is inserted @@ -1216,7 +1224,9 @@ clause `before` a clause that is ordered differently in different dialects, your new clause may also end up in a different place. The only clause so far where that would matter is `:set` which differs in - MySQL." + MySQL. + + Use `clause-order` to see the full ordering of existing clauses." [clause formatter before] (let [clause (sym->kw clause) before (sym->kw before)] From 2fe083f8e60c3876ba7f103aae5f54e8f262a761 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 17:04:48 -0700 Subject: [PATCH 213/254] Support named arguments in format again With the advent of Clojure 1.11 and the ability to call functions that accept named arguments using a hash map, I have restored the named argument version of `format` (in addition to the hash map version), and if you are using Clojure 1.11 you can mix'n'match styles. --- doc/differences-from-1-x.md | 7 ++++--- src/honey/sql.cljc | 3 ++- test/honey/sql_test.cljc | 27 ++++++++++++++++++++++++++- 3 files changed, 32 insertions(+), 5 deletions(-) diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 75f7352..1c60189 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -4,7 +4,10 @@ The goal of HoneySQL 1.x and earlier was to provide a DSL for vendor-neutral SQL The goal of HoneySQL 2.x is to provide an easily-extensible DSL for SQL, supporting vendor-specific differences and extensions, that is as consistent as possible. A secondary goal is to make maintenance much easier by streamlining the machinery and reducing the number of different ways to write and/or extend the DSL. -The DSL itself -- the data structures that both versions convert to SQL and parameters via the `format` function -- is almost exactly the same between the two versions so that migration is relatively painless. The primary API -- the `format` function -- is preserved in 2.x, although the variadic options from 1.x have changed to an options hash map in 2.x as this is generally considered more idiomatic. See the **Option Changes** section below for the differences in the options supported. +The DSL itself -- the data structures that both versions convert to SQL and parameters via the `format` function -- is almost exactly the same between the two versions so that migration is relatively painless. The primary API -- the `format` function -- is preserved in 2.x, although the options have changed between 1.x and 2.x. See the **Option Changes** section below for the differences in the options supported. +`format` can accept its options as a single hash map or as named arguments (v1 only supported the latter). +If you are using Clojure 1.11, you can invoke `format` with a mixture of named arguments and a trailing hash +map of additional options, if you wish. HoneySQL 1.x supported Clojure 1.7 and later. HoneySQL 2.x requires Clojure 1.9 or later. @@ -78,8 +81,6 @@ You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialec ## Option Changes -As noted above, the variadic options for `format` have been replaced by a single hash map as the optional second argument to `format`. - The `:quoting ` option has superseded by the new dialect machinery and a new `:quoted` option that turns quoting on or off. You either use `:dialect ` instead or set a default dialect (via `set-dialect!`) and then use `:quoted true` in `format` calls where you want quoting. Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index baf0ce3..5be39e2 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -1192,7 +1192,8 @@ (:quoted opts) dialect?) *params* (:params opts)] - (mapv #(unwrap % opts) (format-dsl data opts)))))) + (mapv #(unwrap % opts) (format-dsl data opts))))) + ([data k v & {:as opts}] (format data (assoc opts k v)))) (defn set-dialect! "Set the default dialect for formatting. diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 1ccafa1..6b4d4ff 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -2,7 +2,8 @@ (ns honey.sql-test (:refer-clojure :exclude [format]) - (:require #?(:clj [clojure.test :refer [deftest is testing]] + (:require [clojure.string :as str] + #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sut :refer [format]] [honey.sql.helpers :as h])) @@ -383,6 +384,30 @@ :where [:= :bar.b 42]} (format {:dialect :mysql}))))) +(deftest format-arity-test + (testing "format can be called with no options" + (is (= ["DELETE FROM foo WHERE foo.id = ?" 42] + (-> {:delete-from :foo + :where [:= :foo.id 42]} + (format))))) + (testing "format can be called with an options hash map" + (is (= ["\nDELETE FROM `foo`\nWHERE `foo`.`id` = ?\n" 42] + (-> {:delete-from :foo + :where [:= :foo.id 42]} + (format {:dialect :mysql :pretty true}))))) + (testing "format can be called with named arguments" + (is (= ["\nDELETE FROM `foo`\nWHERE `foo`.`id` = ?\n" 42] + (-> {:delete-from :foo + :where [:= :foo.id 42]} + (format :dialect :mysql :pretty true))))) + (when (str/starts-with? #?(:clj (clojure-version) + :cljs *clojurescript-version*) "1.11") + (testing "format can be called with mixed arguments" + (is (= ["\nDELETE FROM `foo`\nWHERE `foo`.`id` = ?\n" 42] + (-> {:delete-from :foo + :where [:= :foo.id 42]} + (format :dialect :mysql {:pretty true}))))))) + (deftest delete-from-test (is (= ["DELETE FROM `foo` WHERE `foo`.`id` = ?" 42] (-> {:delete-from :foo From 8f7c990eed010504fca5da1bbf7e3b6c318b003b Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 17:23:39 -0700 Subject: [PATCH 214/254] Complete special syntax docs --- doc/clause-reference.md | 6 +++++- doc/special-syntax.md | 20 +++++++++++++++++--- 2 files changed, 22 insertions(+), 4 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index e94a87b..00a3681 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -17,6 +17,10 @@ DDL clauses are listed first, followed by SQL clauses. HoneySQL supports the following DDL clauses as a data DSL. +Several of these include column specifications and HoneySQL +provides some special syntax (functions) to support that. +See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. + ## alter-table, add-column, drop-column, modify-column, rename-column `:alter-table` can accept either a single table name or @@ -118,7 +122,7 @@ will be uppercased (mostly to give the appearance of separating the column name from the SQL keywords). Various function-like expressions can be specified, as shown -in the example above, but allow things like `CHECK` for a +in the example above, that allow things like `CHECK` for a constraint, `FOREIGN KEY` (with a column name), `REFERENCES` (with a pair of column names). See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. diff --git a/doc/special-syntax.md b/doc/special-syntax.md index 46d4e07..afce294 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -67,11 +67,24 @@ SQL entity. This is intended for use in contexts that would otherwise produce a sequence of SQL keywords, such as when constructing DDL statements. +```clojure +[:tablespace :quux] +;;=> TABLESPACE QUUX +[:tablespace [:entity :quux]] +;;=> TABLESPACE quux +``` + ## escape Intended to be used with regular expression patterns to specify the escape characters (if any). +```clojure +(format {:select :* :from :foo + :where [:similar-to :foo [:escape "bar" [:inline "*"]]]}) +;;=> ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"])))) +``` + ## inline Accepts a single argument and tries to render it as a @@ -101,7 +114,8 @@ that represents a time unit. Produces an `INTERVAL` expression: ## lateral Accepts a single argument that can be a (`SELECT`) clause or -a (function call) expression. +a (function call) expression. Produces a `LATERAL` subquery +clause based on the `SELECT` clause or the SQL expression. ## lift @@ -230,7 +244,7 @@ Otherwise, these render as regular function calls: [:primary-key :x :y] ;=> PRIMARY KEY(x, y) ``` -## constraint, default, references +### constraint, default, references Although these are grouped together, they are generally used differently. This group renders as SQL keywords if @@ -248,7 +262,7 @@ followed by the rest as a regular argument list: [:references :foo :bar] ;=> REFERENCES foo(bar) ``` -## index, unique +### index, unique These behave like the group above except that if the first argument is `nil`, it is omitted: From 2da32c70f1ede49a5df21ba13aaf12367b9596f4 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 17:35:39 -0700 Subject: [PATCH 215/254] Clause reference tweaks/reordering --- doc/clause-reference.md | 101 +++++++++++++++++++++++----------------- 1 file changed, 59 insertions(+), 42 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 00a3681..992a348 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -167,9 +167,13 @@ a flag indicating the creation should be conditional (`:if-not-exists` or the symbol `if-not-exists`). See the [PostgreSQL](postgresql.md) section for examples. -## create-view, create-materialized-view +## create-view, create-materialized-view, refresh-materialized-view -`:create-view` and `:create-materialized-view` both accept a single view name: +`:create-view`, `:create-materialized-view`, and +`:refresh-materialized-view` all accept a single view name +or a sequence of optional modifiers, followed by the view name, +followed by a flag indicating the creation should be conditional +(`:if-not-exists` or the symbol `if-not-exists`): ```clojure user=> (sql/format {:create-view :products @@ -177,14 +181,22 @@ user=> (sql/format {:create-view :products :from [:items] :where [:= :category "product"]}) ["CREATE VIEW products AS SELECT * FROM items WHERE category = ?" "product"] +user=> (sql/format {:create-view [:products :if-not-exists] + :select [:*] + :from [:items] + :where [:= :category "product"]}) +["CREATE VIEW IF NOT EXISTS products AS SELECT * FROM items WHERE category = ?" "product"] +user=> (sql/format {:refresh-materialized-view [:concurrently :products] + :with-data false}) +["REFRESH MATERIALIZED VIEW CONCURRENTLY products WITH NO DATA"] ``` -## drop-table +## drop-table, drop-extension, drop-view, drop-materialized-view -`:drop-table` can accept a single table name or a sequence of -table names. If a sequence is provided and the first element +`:drop-table` et al can accept a single table (extension, view) name or a sequence of +table (extension, view) names. If a sequence is provided and the first element is `:if-exists` (or the symbol `if-exists`) then that conditional -clause is added before the table names: +clause is added before the table (extension, view) names: ```clojure user=> (sql/format '{drop-table (if-exists foo bar)}) @@ -302,6 +314,19 @@ user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]] HoneySQL does not yet support `SELECT .. INTO ..` or `SELECT .. BULK COLLECT INTO ..`. +## select-distinct-on + +Similar to `:select-distinct` above but the first element +in the sequence should be a sequence of columns for the +`DISTINCT ON` clause and the remaining elements are the +columns to be selected: + +```clojure +user=> (sql/format '{select-distinct-on [[a b] c d] + from [table]}) +["SELECT DISTINCT ON(a, b) c, d FROM table"] +``` + ## select-top, select-distinct-top `:select-top` and `:select-distinct-top` are variants of `:select` @@ -321,20 +346,6 @@ the symbols `percent` and/or `with-ties`). user=> (sql/format {:select-top [[10 :percent :with-ties] :foo :baz] :from :bar :order-by [:quux]}) ["SELECT TOP(?) PERCENT WITH TIES foo, baz FROM bar ORDER BY quux ASC" 10] ``` - -## select-distinct-on - -Similar to `:select-distinct` above but the first element -in the sequence should be a sequence of columns for the -`DISTINCT ON` clause and the remaining elements are the -columns to be selected: - -```clojure -user=> (sql/format '{select-distinct-on [[a b] c d] - from [table]}) -["SELECT DISTINCT ON(a, b) c, d FROM table"] -``` - ## into Used for selecting rows into a new table, optional in another database: @@ -511,6 +522,28 @@ for more detail). > Note: the actual formatting of a `:using` clause is currently identical to the formatting of a `:select` clause. +## join-by + +This is a convenience that allows for an arbitrary sequence of `JOIN` +operations to be performed in a specific order. It accepts a sequence +of join operation name (keyword or symbol) and the clause that join +would take: + +```clojure +user=> (sql/format {:select [:t.ref :pp.code] + :from [[:transaction :t]] + :join-by [:left [[:paypal-tx :pp] + [:using :id]] + :join [[:logtransaction :log] + [:= :t.id :log.id]]] + :where [:= "settled" :pp.status]}) +["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id WHERE ? = pp.status" "settled"] +``` + +Without `:join-by`, a `:join` would normally be generated before a `:left-join`. +To avoid repetition, `:join-by` allows shorthand versions of the join clauses +using a keyword (or symbol) without the `-join` suffix, as shown in this example. + ## join, left-join, right-join, inner-join, outer-join, full-join All these join clauses have the same structure: they accept a sequence @@ -548,28 +581,6 @@ table name and an alias. > Note: the actual formatting of a `:cross-join` clause is currently identical to the formatting of a `:select` clause. -## join-by - -This is a convenience that allows for an arbitrary sequence of `JOIN` -operations to be performed in a specific order. It accepts a sequence -of join operation name (keyword or symbol) and the clause that join -would take: - -```clojure -user=> (sql/format {:select [:t.ref :pp.code] - :from [[:transaction :t]] - :join-by [:left [[:paypal-tx :pp] - [:using :id]] - :join [[:logtransaction :log] - [:= :t.id :log.id]]] - :where [:= "settled" :pp.status]}) -["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id WHERE ? = pp.status" "settled"] -``` - -Without `:join-by`, a `:join` would normally be generated before a `:left-join`. -To avoid repetition, `:join-by` allows shorthand versions of the join clauses -using a keyword (or symbol) without the `-join` suffix, as shown in this example. - ## set (MySQL) This is the precedence of the `:set` clause for the MySQL dialect. @@ -846,3 +857,9 @@ simple table name (keyword or symbol) or a pair of a table name and an alias. > Note: the actual formatting of a `:returning` clause is currently identical to the formatting of a `:select` clause. + +## with-data + +`:with-data` accepts a single boolean argument and produces +either `WITH DATA`, for a `true` argument, or `WITH NO DATA`, +for a `false` argument. From c2e8bb91936d14b09e16fb5332d02f084b147172 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 17:48:13 -0700 Subject: [PATCH 216/254] Finish off the PostgreSQL comparison docs --- doc/clause-reference.md | 14 ++++++++++++-- doc/getting-started.md | 2 +- doc/postgresql.md | 20 ++++++++++++++++++-- 3 files changed, 31 insertions(+), 5 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 992a348..a51cc7c 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -629,14 +629,24 @@ user=> (sql/format {:select [:id :MaxSalary]]]] :from [:employee] :window [:w {:partition-by [:department]}]}) -["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] +;; newlines inserted for readability: +["SELECT id, + AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, + MAX(salary) OVER w AS MaxSalary + FROM employee + WINDOW w AS (PARTITION BY department)"] ;; easier to write with helpers (and easier to read!): user=> (sql/format (-> (select :id (over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average] [[:max :salary] :w :MaxSalary])) (from :employee) (window :w (partition-by :department)))) -["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"] +;; newlines inserted for readability: +["SELECT id, + AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, + MAX(salary) OVER w AS MaxSalary + FROM employee + WINDOW w AS (PARTITION BY department)"] ``` The window function in the `:over` expression may be `{}` or `nil`: diff --git a/doc/getting-started.md b/doc/getting-started.md index 05f4326..74c83e4 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -190,7 +190,7 @@ There is a helper function for every single clause that HoneySQL supports out of the box. In addition, there are helpers for `composite`, `lateral`, `over`, and `upsert` that make it easier to construct those parts of the SQL DSL (examples of `composite` appear in the [README](README.md), -examples of `over` appear in the [Clause Reference](docs/clause-reference.md)) +examples of `over` appear in the [Clause Reference](clause-reference.md)) In addition to being variadic -- which often lets you omit one level of `[`..`]` -- the helper functions merge clauses, which diff --git a/doc/postgresql.md b/doc/postgresql.md index 2a9e535..8b4ceff 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -5,7 +5,7 @@ features that HoneySQL supports out of the box for which you previously needed the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres). -Everything that the nilenso library provided is implemented +Everything that the nilenso library provided (in 0.3.104) is implemented directly in HoneySQL 2.x although a few things have a slightly different syntax. @@ -79,7 +79,7 @@ user=> (-> (insert-into :distributors) ``` `ON CONSTRAINT` is handled slightly differently to the nilenso library, -with provided a single `on-conflict-constraint` helper (and clause): +which provided a single `on-conflict-constraint` helper (and clause): ```clojure user=> (-> (insert-into :distributors) @@ -153,6 +153,18 @@ By comparison, this is the DSL structure that nilenso would have required: ## INSERT INTO AS +HoneySQL supports aliases directly in `:insert-into` so no special +clause is needed for this any more: + +```clojure +user=> (sql/format (-> (insert-into :table :alias) + (values [[1 2 3] [4 5 6]]))) +["INSERT INTO table AS alias VALUES (?, ?, ?), (?, ?, ?)" 1 2 3 4 5 6] +user=> (sql/format {:insert-into [:table :alias], + :values [[1 2 3] [4 5 6]]}) +["INSERT INTO table AS alias VALUES (?, ?, ?), (?, ?, ?)" 1 2 3 4 5 6] +``` + ## Returning The `RETURNING` clause is supported identically to the nilenso library: @@ -325,3 +337,7 @@ user=> (sql/format (alter-table :fruit ``` ## Window / Partition Support + +HoneySQL supports `:window`, `:partition-by`, and `:over` +directly now. +See the Clause Reference for examples of [WINDOW, PARTITION BY, and OVER](clause-reference.md#window-partition-by-and-over). From 0411364ee5a81c6e433e1790240beac14ae07393 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 18:06:57 -0700 Subject: [PATCH 217/254] Addresses #314 by documenting composite --- doc/general-reference.md | 23 ++++++++++++++++++++++- 1 file changed, 22 insertions(+), 1 deletion(-) diff --git a/doc/general-reference.md b/doc/general-reference.md index c1c2cf2..4841d21 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -9,7 +9,28 @@ See #313 ## Tuples and Composite Values -See #314 +Some databases support "composite values" which are usually +represented as tuples in SQL, eg., `(col1,col2)` or `(13,42,'foo')`. +In HoneySQL v1, you could sometimes get away with just using a +vector of entities and/or values, but it was very much dependent +on the context. HoneySQL v2 always treats vectors (and sequences) +as function calls (which may be "special syntax" or an actual +function call). + +HoneySQL provides `:composite` as special syntax to construct +these tuples: + +```clojure +(sql/format-expr [:composite :col1 :col2]) +;;=> ["(col1, col2)"] +(sql/format-expr [:composite 13 42 "foo"]) +;;=> ["(?, ?, ?)" 13 42 "foo"] +;; or using symbols: +(sql/format-expr '(composite col1 col2)) +;;=> ["(col1, col2)"] +(sql/format-expr '(composite 13 42 "foo")) +;;=> ["(?, ?, ?)" 13 42 "foo"] +``` ## Other Sections Will Be Added! From 1548433c02e4f92681449942565c3c5531d64cc0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 18:39:01 -0700 Subject: [PATCH 218/254] WIP on entities --- doc/general-reference.md | 51 +++++++++++++++++++++++++++++++++++++++- 1 file changed, 50 insertions(+), 1 deletion(-) diff --git a/doc/general-reference.md b/doc/general-reference.md index 4841d21..9614e61 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -5,7 +5,56 @@ how to generate certain SQL constructs. ## SQL Entity Generation -See #313 +HoneySQL treats keywords and symbols as SQL entities (in any context other +than function call position in a sequence). If quoting is in effect, +either because `:dialect` was specified as an option to `format` or +because `:quoted true` was specified, the literal name of an unqualified, +single-segment keyword or symbol is used as-is and quoted: + +```clojure +(sql/format {:select :foo-bar} {:quoted true}) +;;=> ["SELECT \"foo-bar\""] +(sql/format {:select :foo-bar} {:dialect :mysql}) +;;=> ["SELECT `foo-bar`"] +``` + +If quoting is not in effect, any dashes (`-`) in the name will be converted to underscores (`_`): + +```clojure +(sql/format {:select :foo-bar}) +;;=> ["SELECT foo_bar"] +(sql/format {:select :foo-bar} {:dialect :mysql :quoted false}) +;;=> ["SELECT foo_bar"] +``` + +If a keyword or symbol contains a dot (`.`), it will be split apart +and treated as a table (or alias) name and a column name: + +```clojure +(sql/format {:select :foo-bar.baz-quux} {:quoted true}) +;;=> ["SELECT \"foo-bar\".\"baz-quux\""] +(sql/format {:select :foo-bar.baz-quux} {:dialect :mysql}) +;;=> ["SELECT `foo-bar`.`baz-quux`"] +(sql/format {:select :foo-bar.baz-quux}) +;;=> ["SELECT foo_bar.baz_quux"] +(sql/format {:select :foo-bar.baz-quux} {:dialect :mysql :quoted false}) +;;=> ["SELECT foo_bar.baz_quux"] +``` + +A qualified keyword or symbol, will also be split apart: + +```clojure +(sql/format {:select :foo-bar/baz-quux} {:quoted true}) +;;=> ["SELECT \"foo_bar\".\"baz-quux\""] +(sql/format {:select :foo-bar/baz-quux} {:dialect :mysql}) +;;=> ["SELECT `foo_bar`.`baz-quux`"] +(sql/format {:select :foo-bar/baz-quux}) +;;=> ["SELECT foo_bar.baz_quux"] +(sql/format {:select :foo-bar/baz-quux} {:dialect :mysql :quoted false}) +;;=> ["SELECT foo_bar.baz_quux"] +``` + +Combining dotted names and.. ## Tuples and Composite Values From cf7e36a131a84db5213b46f39af4d6a4fe277af8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 23:07:19 -0700 Subject: [PATCH 219/254] Addresses #313 by documenting entity formatting in detail --- doc/general-reference.md | 29 +++++++++++++++++++++++------ 1 file changed, 23 insertions(+), 6 deletions(-) diff --git a/doc/general-reference.md b/doc/general-reference.md index 9614e61..7fb4825 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -41,20 +41,37 @@ and treated as a table (or alias) name and a column name: ;;=> ["SELECT foo_bar.baz_quux"] ``` -A qualified keyword or symbol, will also be split apart: +A qualified keyword or symbol, will also be split apart, but dashes (`-`) +in the namespace portion _will_ be converted to underscores (`_`) even +when quoting is in effect: ```clojure (sql/format {:select :foo-bar/baz-quux} {:quoted true}) -;;=> ["SELECT \"foo_bar\".\"baz-quux\""] +;;=> ["SELECT \"foo_bar\".\"baz-quux\""] ; _ in table, - in column (sql/format {:select :foo-bar/baz-quux} {:dialect :mysql}) -;;=> ["SELECT `foo_bar`.`baz-quux`"] +;;=> ["SELECT `foo_bar`.`baz-quux`"] ; _ in table, - in column (sql/format {:select :foo-bar/baz-quux}) -;;=> ["SELECT foo_bar.baz_quux"] +;;=> ["SELECT foo_bar.baz_quux"] ; _ in table and _ in column (sql/format {:select :foo-bar/baz-quux} {:dialect :mysql :quoted false}) -;;=> ["SELECT foo_bar.baz_quux"] +;;=> ["SELECT foo_bar.baz_quux"] ; _ in table and _ in column ``` -Combining dotted names and.. +Finally, there are some contexts where only a SQL entity is accepted, rather than an +arbitrary SQL expression, so a string will be treated as a SQL entity and in such cases +the entity name will always be quoted, dashes (`-`) will not be converted to +underscores (`_`), and a slash (`/`) is not treated as separating a +qualifier from the name, regardless of the `:dialect` or `:quoted` settings: + +```clojure +(sql/format {:update :table :set {"foo-bar" 1 "baz/quux" 2}}) +;;=> ["UPDATE table SET \"foo-bar\" = ?, \"baz/quux\" = ?" 1 2] +(sql/format {:update :table :set {"foo-bar" 1 "baz/quux" 2}} {:quoted true}) +;;=> ["UPDATE \"table\" SET \"foo-bar\" = ?, \"baz/quux\" = ?" 1 2] +(sql/format {:update :table :set {"foo-bar" 1 "baz/quux" 2}} {:dialect :mysql}) +;;=> ["UPDATE `table` SET `foo-bar` = ?, `baz/quux` = ?" 1 2] +(sql/format {:update :table :set {"foo-bar" 1 "baz/quux" 2}} {:dialect :sqlserver :quoted false}) +;;=> ["UPDATE table SET [foo-bar] = ?, [baz/quux] = ?" 1 2] +``` ## Tuples and Composite Values From 88282ee258c216057c310ac0fdb65aec757fc4eb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 23:41:59 -0700 Subject: [PATCH 220/254] Fixes #316 by adding check on entity characters Also record that documentation addresses #300, #309, #313, and #314. --- CHANGELOG.md | 4 + doc/clause-reference.md | 2 + src/honey/sql.cljc | 22 ++-- src/honey/sql/helpers.cljc | 34 +++++- test/honey/sql/helpers_test.cljc | 179 +++++++++++++++++++++---------- test/honey/sql_test.cljc | 14 +++ 6 files changed, 186 insertions(+), 69 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 8f8fa6d..2a0419b 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,8 +1,10 @@ # Changes * 2.0.next in progress + * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). * Fix #319 by ensuring `register-clause!` is idempotent. * Fix #317 by dropping qualifiers in `:set` clauses (just like we do with `:insert` columns). Note that you can still use explicit _dotted_ names if you want table qualification. + * Fix #316 by disallowing entity names containing `;` (to avoid SQL injection risks). * Fix #312 by adding `:raw` as a clause. There is no helper function equivalent (because it would be ambiguous whether you meant a function form -- `[:raw ..]` -- or a clause form -- `{:raw ..}`; and for the same reason, there is no `nest` helper function since that also works as a clause and as a function/special syntax). * 2.0.0-alpha3 (for early testing; 2021-03-13) @@ -21,9 +23,11 @@ * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. + * 2.0.0-alpha2 (for early testing) * Since Alpha 1, a lot more documentation has been written and docstrings have been added to most functions in `honey.sql.helpers`. * Numerous small improvements have been made to clauses and helpers around insert/upsert. + * 2.0.0-alpha1 (for early testing) * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index a51cc7c..a482ac4 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -428,6 +428,8 @@ user=> (sql/format '{insert-into (((transport t) (id, name)) {select (*) from (c ["INSERT INTO transport AS t (id, name) SELECT * FROM cars"] ``` +> Note: if you specify `:columns` for an `:insert-into` that also includes column names, you will get invalid SQL. Similarly, if you specify `:columns` when `:values` is based on hash maps, you will get invalid SQL. Since clauses are generated independently, there is no cross-checking performed if you provide an illegal combination of clauses. + ## update `:update` expects either a simple SQL entity (table name) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 5be39e2..d138306 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -98,6 +98,10 @@ (def ^:private ^:dynamic *quoted* nil) (def ^:private ^:dynamic *inline* nil) (def ^:private ^:dynamic *params* nil) +;; there is no way, currently, to enable suspicious characters +;; in entities; if someone complains about this check, an option +;; can be added to format to turn this on: +(def ^:private ^:dynamic *allow-suspicious-entities* false) ;; clause helpers @@ -164,12 +168,18 @@ (if aliased [nil (nn x)] (let [[t c] (str/split (nn x) #"\.")] - (if c [t c] [nil t]))))] - (cond->> c - (not= "*" c) - (q) - t - (str (q t) ".")))) + (if c [t c] [nil t])))) + entity (cond->> c + (not= "*" c) + (q) + t + (str (q t) ".")) + suspicious #";"] + (when-not *allow-suspicious-entities* + (when (re-find suspicious entity) + (throw (ex-info (str "suspicious character found in entity: " entity) + {:disallowed suspicious})))) + entity)) (comment (for [v [:foo-bar 'foo-bar "foo-bar" diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 8f9b4d4..5a1832f 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -592,12 +592,26 @@ (defn where "Accepts one or more SQL expressions (conditions) and - combines them with AND: + combines them with AND (by default): (where [:= :status 0] [:<> :task \"backup\"]) + or: + (where :and [:= :status 0] [:<> :task \"backup\"]) Produces: WHERE (status = ?) AND (task <> ?) - Parameters: 0 \"backup\"" + Parameters: 0 \"backup\" + + For a single expression, the brackets can be omitted: + + (where := :status 0) ; same as (where [:= :status 0]) + + With multiple expressions, the conjunction may be + specified as a leading symbol: + + (where :or [:= :status 0] [:= :task \"stop\"]) + + Produces: WHERE (status = 0) OR (task = ?) + Parameters: 0 \"stop\"" [& exprs] (generic :where exprs)) @@ -615,12 +629,24 @@ (defn having "Like `where`, accepts one or more SQL expressions - (conditions) and combines them with AND: + (conditions) and combines them with AND (by default): (having [:> :count 0] [:<> :name nil]) + or: + (having :and [:> :count 0] [:<> :name nil]) Produces: HAVING (count > ?) AND (name IS NOT NULL) - Parameters: 0" + Parameters: 0 + + (having :> :count 0) + + Produces: HAVING count > ? + Parameters: 0 + + (having :or [:> :count 0] [:= :name \"\"]) + + Produces: HAVING (count > ?) OR (name = ?) + Parameters: 0 \"\"" [& exprs] (generic :having exprs)) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 21b2e38..8daa0eb 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -20,65 +20,126 @@ with-data]])) (deftest test-select - (let [m1 (-> (with [:cte (-> (select :*) - (from :example) - (where [:= :example-column 0]))]) - (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"] - :%now [[:raw "@x := 10"]]) - (from [:foo :f] [:baz :b]) - (join :draq [:= :f.b :draq.x]) - (left-join [:clod :c] [:= :f.a :c.d]) - (right-join :bock [:= :bock.z :c.e]) - (full-join :beck [:= :beck.x :c.y]) - (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:and [:< 1 2] [:< 2 3]] - [:in :f.e [1 [:param :param2] 3]] - [:between :f.e 10 20]]) - (group-by :f.a) - (having [:< 0 :f.e]) - (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) - (limit 50) - (offset 10)) - m2 {:with [[:cte {:select [:*] - :from [:example] - :where [:= :example-column 0]}]] - :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] - :%now [[:raw "@x := 10"]]] - :from [[:foo :f] [:baz :b]] - :join [:draq [:= :f.b :draq.x]] - :left-join [[:clod :c] [:= :f.a :c.d]] - :right-join [:bock [:= :bock.z :c.e]] - :full-join [:beck [:= :beck.x :c.y]] - :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:and [:< 1 2] [:< 2 3]] - [:in :f.e [1 [:param :param2] 3]] - [:between :f.e 10 20]] - :group-by [:f.a] - :having [:< 0 :f.e] - :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] - :limit 50 - :offset 10}] - (testing "Various construction methods are consistent" - (is (= m1 m2))) - (testing "SQL data formats correctly" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) - #?(:clj (testing "SQL data prints and reads correctly" - (is (= m1 (read-string (pr-str m1)))))) - #_(testing "SQL data formats correctly with alternate param naming" - (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) - ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) - (testing "Locking" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format (assoc m1 :lock [:in-share-mode]) - {:params {:param1 "gabba" :param2 2} - ;; to enable :lock - :dialect :mysql :quoted false})))))) + (testing "large helper expression" + (let [m1 (-> (with [:cte (-> (select :*) + (from :example) + (where [:= :example-column 0]))]) + (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]) + (from [:foo :f] [:baz :b]) + (join :draq [:= :f.b :draq.x]) + (left-join [:clod :c] [:= :f.a :c.d]) + (right-join :bock [:= :bock.z :c.e]) + (full-join :beck [:= :beck.x :c.y]) + (where [:or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:and [:< 1 2] [:< 2 3]] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]]) + (group-by :f.a) + (having [:< 0 :f.e]) + (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) + (limit 50) + (offset 10)) + m2 {:with [[:cte {:select [:*] + :from [:example] + :where [:= :example-column 0]}]] + :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]] + :from [[:foo :f] [:baz :b]] + :join [:draq [:= :f.b :draq.x]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :right-join [:bock [:= :bock.z :c.e]] + :full-join [:beck [:= :beck.x :c.y]] + :where [:or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:and [:< 1 2] [:< 2 3]] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]] + :group-by [:f.a] + :having [:< 0 :f.e] + :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] + :limit 50 + :offset 10}] + (testing "Various construction methods are consistent" + (is (= m1 m2))) + (testing "SQL data formats correctly" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) + #?(:clj (testing "SQL data prints and reads correctly" + (is (= m1 (read-string (pr-str m1)))))) + #_(testing "SQL data formats correctly with alternate param naming" + (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) + ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) + (testing "Locking" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format (assoc m1 :lock [:in-share-mode]) + {:params {:param1 "gabba" :param2 2} + ;; to enable :lock + :dialect :mysql :quoted false})))))) + (testing "large helper expression with simplified where" + (let [m1 (-> (with [:cte (-> (select :*) + (from :example) + (where := :example-column 0))]) + (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]) + (from [:foo :f] [:baz :b]) + (join :draq [:= :f.b :draq.x]) + (left-join [:clod :c] [:= :f.a :c.d]) + (right-join :bock [:= :bock.z :c.e]) + (full-join :beck [:= :beck.x :c.y]) + (where :or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:and [:< 1 2] [:< 2 3]] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]) + (group-by :f.a) + (having :< 0 :f.e) + (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) + (limit 50) + (offset 10)) + m2 {:with [[:cte {:select [:*] + :from [:example] + :where [:= :example-column 0]}]] + :select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"] + :%now [[:raw "@x := 10"]]] + :from [[:foo :f] [:baz :b]] + :join [:draq [:= :f.b :draq.x]] + :left-join [[:clod :c] [:= :f.a :c.d]] + :right-join [:bock [:= :bock.z :c.e]] + :full-join [:beck [:= :beck.x :c.y]] + :where [:or + [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] + [:and [:< 1 2] [:< 2 3]] + [:in :f.e [1 [:param :param2] 3]] + [:between :f.e 10 20]] + :group-by [:f.a] + :having [:< 0 :f.e] + :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] + :limit 50 + :offset 10}] + (testing "Various construction methods are consistent" + (is (= m1 m2))) + (testing "SQL data formats correctly" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ?" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format m1 {:params {:param1 "gabba" :param2 2}})))) + #?(:clj (testing "SQL data prints and reads correctly" + (is (= m1 (read-string (pr-str m1)))))) + #_(testing "SQL data formats correctly with alternate param naming" + (is (= (sql/format m1 {:params {:param1 "gabba" :param2 2}}) + ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla \"bla-bla\", NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2) AND (b.baz <> $3)) OR (($4 < $5) AND ($6 < $7)) OR (f.e IN ($8, $9, $10)) OR f.e BETWEEN $11 AND $12 GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT $14 OFFSET $15" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) + (testing "Locking" + (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS `bla-bla`, NOW(), @x := 10 FROM foo AS f, baz AS b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod AS c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ?) AND (b.baz <> ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ? GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST LIMIT ? OFFSET ? LOCK IN SHARE MODE" + 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] + (sql/format (assoc m1 :lock [:in-share-mode]) + {:params {:param1 "gabba" :param2 2} + ;; to enable :lock + :dialect :mysql :quoted false}))))))) (deftest select-top-tests (testing "Basic TOP syntax" diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 6b4d4ff..b7fe742 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -649,6 +649,20 @@ ORDER BY id = ? DESC :values [{:name name :enabled enabled}]}))))) +(deftest issue-316-test + (testing "SQL injection via keyword is detected" + (let [sort-column "foo; select * from users"] + (try + (-> {:select [:foo :bar] + :from [:mytable] + :order-by [(keyword sort-column)]} + (format)) + (is false "; not detected in entity!") + (catch #?(:clj Throwable :cljs :default) e + (is (:disallowed (ex-data e)))))) + ;; should not produce: ["SELECT foo, bar FROM mytable ORDER BY foo; select * from users"] + )) + (deftest issue-319-test (testing "that registering a clause is idempotent" (is (= ["FOO"] From 35c6fc58a57e47908d8e1b1f175760213798c6e0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Fri, 9 Apr 2021 23:51:31 -0700 Subject: [PATCH 221/254] Prep for 2.0.0 Beta 1 --- CHANGELOG.md | 2 +- README.md | 2 +- doc/general-reference.md | 2 +- doc/getting-started.md | 6 +++--- pom.xml | 4 ++-- 5 files changed, 8 insertions(+), 8 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 2a0419b..458adaa 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,6 @@ # Changes -* 2.0.next in progress +* 2.0.0-beta1 (for testing; 2021-04-09) * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). * Fix #319 by ensuring `register-clause!` is idempotent. * Fix #317 by dropping qualifiers in `:set` clauses (just like we do with `:insert` columns). Note that you can still use explicit _dotted_ names if you want table qualification. diff --git a/README.md b/README.md index edab11b..95c6a94 100644 --- a/README.md +++ b/README.md @@ -12,7 +12,7 @@ This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINO Prerelease builds of the upcoming 2.x version of HoneySQL are available for testing: -[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-alpha3)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1) HoneySQL 2.x requires Clojure 1.9 or later. diff --git a/doc/general-reference.md b/doc/general-reference.md index 7fb4825..d4a29fd 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -110,6 +110,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.0, this [overview of differences between 1.0 and 2.0](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index 74c83e4..c40c263 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - com.github.seancorfield/honeysql {:mvn/version "2.0.0-alpha3"} + com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta1"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [com.github.seancorfield/honeysql "2.0.0-alpha3"] + [com.github.seancorfield/honeysql "2.0.0-beta1"] ``` HoneySQL produces SQL statements but does not execute them. @@ -318,7 +318,7 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-alpha3/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. More detail about certain core HoneySQL functionality can be found in the [Reference documentation](general-reference.md). If you're migrating to HoneySQL 2.0, this [overview of differences diff --git a/pom.xml b/pom.xml index 37bdc46..f68b9d8 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 com.github.seancorfield honeysql - 2.0.0-alpha3 + 2.0.0-beta1 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-alpha3 + v2.0.0-beta1 From 7a83bc13fe83e6d9988fc4d6648da555f10961d9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 10 Apr 2021 00:13:04 -0700 Subject: [PATCH 222/254] Tweak docstring --- src/honey/sql.cljc | 12 ++++++++---- 1 file changed, 8 insertions(+), 4 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index d138306..6d99710 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -8,20 +8,24 @@ supported syntax. In addition, functions to extend HoneySQL are also provided here: - * `sql-kw` -- turns a Clojure keyword into SQL code (makes it uppercase - and replaces - with space). + * `clause-order` -- returns the current clause priority ordering; + intended as aid when registering new clauses. * `format-dsl` -- intended to format SQL statements; returns a vector containing a SQL string followed by parameter values. + * `format-entity` -- intended to format SQL entities; returns a string + representing the SQL entity. * `format-expr` -- intended to format SQL expressions; returns a vector containing a SQL string followed by parameter values. * `format-expr-list` -- intended to format a list of SQL expressions; returns a pair comprising: a sequence of SQL expressions (to be join with a delimiter) and a sequence of parameter values. - * `set-dialect!` -- set the default dialect to be used for formatting. * `register-clause!` -- register a new statement/clause formatter. * `register-fn!` -- register a new function call (or special syntax) formatter. - * `register-op!` -- register a new operator formatter." + * `register-op!` -- register a new operator formatter. + * `set-dialect!` -- set the default dialect to be used for formatting. + * `sql-kw` -- turns a Clojure keyword (or symbol) into SQL code (makes + it uppercase and replaces - with space). " (:refer-clojure :exclude [format]) (:require [clojure.string :as str])) From f2311512432d44e022d49053658bb9bc0d40d316 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 10 Apr 2021 00:17:42 -0700 Subject: [PATCH 223/254] Fix column descriptors links --- doc/clause-reference.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index a482ac4..3f3fe7e 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -19,7 +19,7 @@ HoneySQL supports the following DDL clauses as a data DSL. Several of these include column specifications and HoneySQL provides some special syntax (functions) to support that. -See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. +See [Column Descriptors in Special Syntax](special-syntax.md#column-descriptors) for more details. ## alter-table, add-column, drop-column, modify-column, rename-column @@ -124,7 +124,7 @@ the column name from the SQL keywords). Various function-like expressions can be specified, as shown in the example above, that allow things like `CHECK` for a constraint, `FOREIGN KEY` (with a column name), `REFERENCES` -(with a pair of column names). See [Clause Descriptors in Special Syntax](special-syntax.md#clause-descriptors) for more details. +(with a pair of column names). See [Column Descriptors in Special Syntax](special-syntax.md#column-descriptors) for more details. ## create-table-as From 8a1e2cca712c52dadbeb26834287968eb650b7e1 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 10 Apr 2021 10:57:13 -0700 Subject: [PATCH 224/254] Addresses #315 by expanding IN to handle nil --- CHANGELOG.md | 3 +++ src/honey/sql.cljc | 33 ++++++++++++++++++------ test/honey/sql/helpers_test.cljc | 43 ++++++++++++++++++++++++++++++++ 3 files changed, 71 insertions(+), 8 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 458adaa..418296c 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.next in progress + * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. + * 2.0.0-beta1 (for testing; 2021-04-09) * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). * Fix #319 by ensuring `register-clause!` is idempotent. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 6d99710..12b951e 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -921,17 +921,34 @@ x)) (defn- format-in [in [x y]] - (let [[sql-x & params-x] (format-expr x {:nested true}) - [sql-y & params-y] (format-expr y {:nested true}) + (let [nil-check (and (sequential? y) (not (ident? (first y)))) + y' (if nil-check (remove nil? y) y) + [sql-x & params-x] (format-expr x {:nested true}) + [sql-y & params-y] (format-expr y' {:nested true}) values (unwrap (first params-y) {})] (if (and (= "?" sql-y) (= 1 (count params-y)) (coll? values)) - (let [sql (str "(" (str/join ", " (repeat (count values) "?")) ")")] - (-> [(str sql-x " " (sql-kw in) " " sql)] + (let [values' (remove nil? values) + sql (str "(" (str/join ", " (repeat (count values') "?")) ")") + in (str sql-x " " (sql-kw in) " " sql)] + (-> [(if (not= (count values) (count values')) + (if (zero? (count values')) + (str sql-x " IS NULL") + (str "(" in " OR " sql-x " IS NULL)")) + (if (zero? (count values)) + "FALSE" + in))] (into params-x) - (into values))) - (-> [(str sql-x " " (sql-kw in) " " sql-y)] - (into params-x) - (into params-y))))) + (into values'))) + (let [in (str sql-x " " (sql-kw in) " " sql-y)] + (-> [(if (and nil-check (not= (count y) (count y'))) + (if (zero? (count y')) + (str sql-x " IS NULL") + (str "(" in " OR " sql-x " IS NULL)")) + (if (zero? (count y)) + "FALSE" + in))] + (into params-x) + (into params-y)))))) (defn- function-0 [k xs] [(str (sql-kw k) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 8daa0eb..b69599f 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -274,6 +274,39 @@ :from [:customers] :where [:in :id values]}))) (is (= ["SELECT * FROM customers WHERE id IN (?)" 1] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}}))))) + (testing (str "with just a nil value from a " (name cname)) + (let [values (conj coll nil)] + (is (= ["SELECT * FROM customers WHERE id IS NULL"] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE id IS NULL"] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}}))))) + (testing (str "with nil values from a " (name cname)) + (let [values (conj coll 1 nil)] + (is (= ["SELECT * FROM customers WHERE (id IN (?) OR id IS NULL)" 1] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE (id IN (?) OR id IS NULL)" 1] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}}))))) + (testing (str "with no values from a " (name cname)) + (let [values coll] + (is (= ["SELECT * FROM customers WHERE FALSE"] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE FALSE"] (sql/format {:select [:*] :from [:customers] :where [:in :id :?ids]} @@ -285,6 +318,16 @@ :from [:customers] :where [:in :id values]}))) (is (= ["SELECT * FROM customers WHERE id IN (?, ?)" 1 2] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id :?ids]} + {:params {:ids values}})))) + (let [values [1 nil 2]] + (is (= ["SELECT * FROM customers WHERE (id IN (?, ?) OR id IS NULL)" 1 2] + (sql/format {:select [:*] + :from [:customers] + :where [:in :id values]}))) + (is (= ["SELECT * FROM customers WHERE (id IN (?, ?) OR id IS NULL)" 1 2] (sql/format {:select [:*] :from [:customers] :where [:in :id :?ids]} From f393a6101083594381d565660f19062d5e5a2e7e Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 10 Apr 2021 03:58:29 -0700 Subject: [PATCH 225/254] Remove honey.specs (for now) #146 --- doc/differences-from-1-x.md | 5 ++--- src/honey/specs.clj | 13 ------------- 2 files changed, 2 insertions(+), 16 deletions(-) delete mode 100644 src/honey/specs.clj diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 1c60189..664f8f9 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -15,7 +15,7 @@ HoneySQL 1.x supported Clojure 1.7 and later. HoneySQL 2.x requires Clojure 1.9 HoneySQL 2.x uses the group ID `com.github.seancorfield` with the original artifact ID of `honeysql`, in line with the recommendations in Inside Clojure's post about the changes in the Clojure CLI: [Deprecated unqualified lib names](https://insideclojure.org/2020/07/28/clj-exec/); also Clojars [Verified Group Names policy](https://github.com/clojars/clojars-web/wiki/Verified-Group-Names). -In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. A Spec for the DSL data structure will be available in `honey.specs` at some point (work in progress). +In addition, HoneySQL 2.x contains different namespaces so you can have both versions on your classpath without introducing any conflicts. The primary API is now in `honey.sql` and the helpers are in `honey.sql.helpers`. ### HoneySQL 1.x @@ -64,8 +64,7 @@ com.github.seancorfield/honeysql {:mvn/version "2.x"} The new namespaces are: * `honey.sql` -- the primary API (just `format` now), -* `honey.sql.helpers` -- helper functions to build the DSL, -* `honey.specs` -- a description of the DSL using `clojure.spec.alpha`. +* `honey.sql.helpers` -- helper functions to build the DSL. Supported Clojure versions: 1.9 and later. diff --git a/src/honey/specs.clj b/src/honey/specs.clj deleted file mode 100644 index 39042bd..0000000 --- a/src/honey/specs.clj +++ /dev/null @@ -1,13 +0,0 @@ -;; copyright (c) 2020-2021 sean corfield, all rights reserved - -(ns honey.specs - "Optional namespace containing `clojure.spec` representations of - the data format used as the underlying DSL for HoneySQL." - (:require [clojure.spec.alpha :as s])) - -(s/def ::sql-expression any?) - -(s/def ::dsl (s/map-of simple-keyword? - (s/coll-of ::sql-expression - :kind vector? - :min-count 1))) From 862a2496c6507bdcec958c5a79c47abab35ea5d9 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 11:09:47 -0700 Subject: [PATCH 226/254] Consistent use of 1.x / 2.x --- CHANGELOG.md | 6 +++--- README.md | 14 +++----------- doc/clause-reference.md | 2 +- doc/differences-from-1-x.md | 20 ++++++++++---------- doc/general-reference.md | 8 ++++---- doc/getting-started.md | 6 +++--- test/honey/sql/postgres_test.cljc | 4 ++-- test/honey/sql_test.cljc | 6 +++--- 8 files changed, 29 insertions(+), 37 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 418296c..d71e514 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -17,13 +17,13 @@ * Fix #305 by supporting more complex join clauses. * Fix #303 by supporting MySQL's `ON DUPLICATE KEY UPDATE`. * Fix #301 by adding support for `CREATE`/`DROP`/`REFRESH` on `MATERIALIZED VIEW`. - * Add tests to confirm #299 does not affect v2. + * Add tests to confirm #299 does not affect 2.x. * Fix #297 by adding both `SELECT .. INTO ..` and `SELECT .. BULK COLLECT INTO ..`. * Fix #295 by adding docstrings to all helper functions (and adding an assert to ensure it stays that way as more are added in future). * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293, but see #310 for recent additions not yet incorporated). * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. * Fix #284 by adding support for `LATERAL` (as special syntax, with a helper). - * Reconcile `where` behavior with recent 1.0 changes (porting #283 to v2). + * Reconcile `where` behavior with recent 1.x changes (porting #283 to 2.x). * Fix #280 by adding `:escape` as special syntax for regular expression patterns. * Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order. @@ -35,7 +35,7 @@ * This is a complete rewrite/simplification of HoneySQL that provides just two namespaces: * `honey.sql` -- this is the primary API via the `format` function as well as the various extension points. * `honey.sql.helpers` -- provides a helper function for every piece of the DSL that is supported out-of-the-box. - * The coordinates for HoneySQL 2.0 are `com.github.seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.0 without any conflicts, making it easier to migrate piecemeal from 1.0 to 2.0. + * The coordinates for HoneySQL 2.x are `com.github.seancorfield/honeysql` so it can be added to a project that already uses HoneySQL 1.x without any conflicts, making it easier to migrate piecemeal from 1.x to 2.x. # HoneySQL pre-2.x Changes diff --git a/README.md b/README.md index 95c6a94..8ebb10a 100644 --- a/README.md +++ b/README.md @@ -4,21 +4,15 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -The latest stable version (1.0.461) on Clojars and on cljdoc (note: `honeysql/honeysql`): - -[![Clojars Project](https://clojars.org/honeysql/honeysql/latest-version.svg)](https://clojars.org/honeysql/honeysql) [![cljdoc badge](https://cljdoc.org/badge/honeysql/honeysql?1.0.461)](https://cljdoc.org/d/honeysql/honeysql/1.0.461) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. -Prerelease builds of the upcoming 2.x version of HoneySQL are available for testing: - -[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1) - HoneySQL 2.x requires Clojure 1.9 or later. -This is the README for the upcoming 2.x version of HoneySQL which provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike the 1.x version). +Compared to 1.x, HoneySQL 2.x provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike 1.x). -See this [summary of differences between v1 and v2](doc/differences-from-1-x.md) if you want to help test v2! +> Note: you can use 1.x and 2.x side-by-side as they use different group IDs and different namespaces. This allows for a piecemeal migration. See this [summary of differences between 1.x and 2.x](doc/differences-from-1-x.md) if you are migrating from 1.x! ## Note on code samples @@ -83,8 +77,6 @@ If you want to format the query as a string with no parameters (e.g. to use the Namespace-qualified keywords are generally treated as table-qualified columns: `:foo/bar` becomes `foo.bar`, except in contexts where that would be illegal (such as the list of columns in an `INSERT` statement). This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. -_[In HoneySQL 1.x, this was the behavior when `:namespace-as-table? true` was specified]_ - ```clojure (def q-sqlmap {:select [:foo/a :foo/b :foo/c] :from [:foo] diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 3f3fe7e..1edc6fb 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -480,7 +480,7 @@ example above with `:insert-into`. that they should be assigned. This precedence -- between `:columns` and `:from` -- corresponds to ANSI SQL which is correct for most databases. The MySQL dialect that -HoneySQL 2.0 supports has a different precedence (below). +HoneySQL 2.x supports has a different precedence (below). ```clojure user=> (sql/format {:update :order diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 664f8f9..dd9a672 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -5,7 +5,7 @@ The goal of HoneySQL 1.x and earlier was to provide a DSL for vendor-neutral SQL The goal of HoneySQL 2.x is to provide an easily-extensible DSL for SQL, supporting vendor-specific differences and extensions, that is as consistent as possible. A secondary goal is to make maintenance much easier by streamlining the machinery and reducing the number of different ways to write and/or extend the DSL. The DSL itself -- the data structures that both versions convert to SQL and parameters via the `format` function -- is almost exactly the same between the two versions so that migration is relatively painless. The primary API -- the `format` function -- is preserved in 2.x, although the options have changed between 1.x and 2.x. See the **Option Changes** section below for the differences in the options supported. -`format` can accept its options as a single hash map or as named arguments (v1 only supported the latter). +`format` can accept its options as a single hash map or as named arguments (1.x only supported the latter). If you are using Clojure 1.11, you can invoke `format` with a mixture of named arguments and a trailing hash map of additional options, if you wish. @@ -49,7 +49,7 @@ Supported Clojure versions: 1.7 and later. ```clojure ;; in deps.edn: -com.github.seancorfield/honeysql {:mvn/version "2.x"} +com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta1"} ;; in use: (ns my.project @@ -85,11 +85,11 @@ The `:quoting ` option has superseded by the new dialect machinery and Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. The following options are no longer supported: -* `:allow-dashed-names?` -- if you provide dashed-names in v2, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). +* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). * `:allow-namespaced-names?` -- this supported `foo/bar` column names in SQL which I'd like to discourage. -* `:namespace-as-table?` -- this is the default in v2: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. +* `:namespace-as-table?` -- this is the default in 2.x: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. * `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). -* `:return-param-names` -- this was added to v1 back in 2013 without an associated issue or PR so I've no idea what use case this was intended to support. +* `:return-param-names` -- this was added to 1.x back in 2013 without an associated issue or PR so I've no idea what use case this was intended to support. > Note: I expect some push back on those first three options and the associated behavior changes. @@ -114,12 +114,12 @@ The following new syntax has been added: * `:not` -- this is now explicit syntax, * `:over` -- the function-like part of a T-SQL window clause, * `:param` -- used as a function to replace the `sql/param` / `#sql/param` machinery, -* `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the v1 behavior but should be more flexible, since you can now embed `:inline`, `:param`, and `:lift` inside a `:raw` expression. +* `:raw` -- used as a function to replace the `sql/raw` / `#sql/raw` machinery. Vector subexpressions inside a `[:raw ..]` expression are formatted to SQL and parameters. Other subexpressions are just turned into strings and concatenated. This is different to the 1.x behavior but should be more flexible, since you can now embed `:inline`, `:param`, and `:lift` inside a `:raw` expression. > Note 1: in 1.x, inlining a string `"foo"` produced `foo` but in 2.x it produces `'foo'`, i.e., string literals become SQL strings without needing internal quotes (1.x required `"'foo'"`). Several additional pieces of syntax have also been added to support column -definitions in `CREATE TABLE` clauses, now that v2 supports DDL statement +definitions in `CREATE TABLE` clauses, now that 2.x supports DDL statement construction: * `:constraint`, `:default`, `:foreign-key`, `:index`, `:primary-key`, `:references`, `:unique`, @@ -135,7 +135,7 @@ user=> (sql/format {:select [:a [:b :c] [[:d :e]] [[:f :g] :h]]}) ["SELECT a, b AS c, D(e), F(g) AS h"] ``` -On a related note, `sql/call` has been removed because it should never be needed now: `[:foo ...]` should always be treated as a function call, consistently, avoiding the special cases in v1 that necessitated the explicit `sql/call` syntax. +On a related note, `sql/call` has been removed because it should never be needed now: `[:foo ...]` should always be treated as a function call, consistently, avoiding the special cases in 1.x that necessitated the explicit `sql/call` syntax. ### select modifiers @@ -173,11 +173,11 @@ You can also register new "functions" that can implement special syntax (such as And, finally, you can register new operators that will be recognized in expressions via `honey.sql/register-op!`. This accepts an operator name as a keyword and optional named parameters to indicate whether the operator is `:variadic` (the default is strictly binary) and whether it should ignore operands that evaluate to `nil` (via `:ignore-nil`). The latter can make it easier to construct complex expressions programmatically without having to worry about conditionally removing "optional" (`nil`) values. -> Note: because of the changes in the extension machinery between v1 and v2, it is not possible to use the https://github.com/nilenso/honeysql-postgres library with HoneySQL v2 but the goal is to incorporate all of the syntax from that library into the core of HoneySQL. +> Note: because of the changes in the extension machinery between 1.x and 2.x, it is not possible to use the https://github.com/nilenso/honeysql-postgres library with HoneySQL 2.x but the goal is to incorporate all of the syntax from that library into the core of HoneySQL. ## Helpers -The `honey.sql.helpers` namespace includes a helper function that corresponds to every supported piece of the data DSL understood by HoneySQL (v1 only had a limited set of helper functions). Unlike v1 helpers which sometimes had both a regular helper and a `merge-` helper, v2 helpers will all merge clauses by default (if that makes sense for the underlying DSL): use `:dissoc` if you want to force an overwrite. +The `honey.sql.helpers` namespace includes a helper function that corresponds to every supported piece of the data DSL understood by HoneySQL (1.x only had a limited set of helper functions). Unlike 1.x helpers which sometimes had both a regular helper and a `merge-` helper, 2.x helpers will all merge clauses by default (if that makes sense for the underlying DSL): use `:dissoc` if you want to force an overwrite. The only helpers that have non-merging behavior are: * The SQL set operations `intersect`, `union`, `union-all`, `except`, and `except-all` which always wrap around their arguments, diff --git a/doc/general-reference.md b/doc/general-reference.md index d4a29fd..d331076 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -77,9 +77,9 @@ qualifier from the name, regardless of the `:dialect` or `:quoted` settings: Some databases support "composite values" which are usually represented as tuples in SQL, eg., `(col1,col2)` or `(13,42,'foo')`. -In HoneySQL v1, you could sometimes get away with just using a +In HoneySQL 1.x, you could sometimes get away with just using a vector of entities and/or values, but it was very much dependent -on the context. HoneySQL v2 always treats vectors (and sequences) +on the context. HoneySQL 2.x always treats vectors (and sequences) as function calls (which may be "special syntax" or an actual function call). @@ -111,5 +111,5 @@ of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the [honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. -If you're migrating to HoneySQL 2.0, this [overview of differences -between 1.0 and 2.0](differences-from-1-x.md) should help. +If you're migrating to HoneySQL 2.x, this [overview of differences +between 1.x and 2.x](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index c40c263..2ad2ce8 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -246,7 +246,7 @@ a lot of PostgreSQL extensions in that mode. PostgreSQL is mostly a superset of ANSI SQL so it makes sense to support as much as possible of the union of ANSI SQL and PostgreSQL out of the box. -The dialects supported by HoneySQL v2 are: +The dialects supported by HoneySQL 2.x are: * `:ansi` -- the default, including most PostgreSQL extensions * `:sqlserver` -- Microsoft SQL Server * `:mysql` -- MySQL (and Percona and MariaDB) @@ -321,5 +321,5 @@ documentation for the helper functions is in the [honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. More detail about certain core HoneySQL functionality can be found in the [Reference documentation](general-reference.md). -If you're migrating to HoneySQL 2.0, this [overview of differences -between 1.0 and 2.0](differences-from-1-x.md) should help. +If you're migrating to HoneySQL 2.x, this [overview of differences +between 1.x and 2.x](differences-from-1-x.md) should help. diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 6074fd5..86d9852 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -1,11 +1,11 @@ ;; copied from https://github.com/nilenso/honeysql-postgres ;; on 2021-02-13 to verify the completeness of support for -;; those features within HoneySQL v2 +;; those features within HoneySQL 2.x ;; where there are differences, the original code is kept ;; with #_ and the modified code follows it (aside from ;; the ns form which has numerous changes to both match -;; the structure of HoneySQL v2 and to work with cljs) +;; the structure of HoneySQL 2.x and to work with cljs) (ns honey.sql.postgres-test (:refer-clojure :exclude [update partition-by set]) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index b7fe742..4dd43dd 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -83,7 +83,7 @@ :from [:Candidate]} :sub-q-alias]]} {:dialect :oracle :quoted false})))) -;; tests lifted from HoneySQL v1 to check for compatibility +;; tests lifted from HoneySQL 1.x to check for compatibility (deftest alias-splitting (is (= ["SELECT `aa`.`c` AS `a.c`, `bb`.`c` AS `b.c`, `cc`.`c` AS `c.c`"] @@ -311,7 +311,7 @@ [:= :quux "quux"]]} {:parameterizer :postgresql}) ["WHERE (foo = ?) AND (bar = $2) AND (quux = $3)" "foo" "bar" "quux"]))) - ;; new :inline option is similar to :parameterizer :none in 1.0 + ;; new :inline option is similar to :parameterizer :none in 1.x (testing "should fill param with single quote" (is (= (format {:where [:and [:= :foo "foo"] @@ -642,7 +642,7 @@ ORDER BY id = ? DESC (deftest issue-299-test (let [name "test field" - ;; this was a bug in v1 -- adding here to prevent regression: + ;; this was a bug in 1.x -- adding here to prevent regression: enabled [true, "); SELECT case when (SELECT current_setting('is_superuser'))='off' then pg_sleep(0.2) end; -- "]] (is (= ["INSERT INTO table (name, enabled) VALUES (?, (TRUE, ?))" name (second enabled)] (format {:insert-into :table From 84147b242dc1322fc2d97954c4c9ea9ee6e068bb Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 11:10:13 -0700 Subject: [PATCH 227/254] Bump depstar --- deps.edn | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/deps.edn b/deps.edn index 1b1e640..380ea0c 100644 --- a/deps.edn +++ b/deps.edn @@ -19,7 +19,7 @@ :main-opts ["-m" "seancorfield.readme"]} :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.4.0"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.206"}} + :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.211"}} :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar" :sync-pom true}} :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} From bbc0ac85009dd5e01bb564fc1aaa837eef14fc80 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 11:39:06 -0700 Subject: [PATCH 228/254] Documentation updates --- CHANGELOG.md | 1 + README.md | 16 +++++++++++++--- doc/clause-reference.md | 3 ++- doc/general-reference.md | 6 +++++- doc/getting-started.md | 19 ++++++++++++++----- src/honey/sql.cljc | 7 ++++++- 6 files changed, 41 insertions(+), 11 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index d71e514..53fee80 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,7 @@ # Changes * 2.0.next in progress + * The documentation continues to be expanded and clarified in respond to feedback! * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. * 2.0.0-beta1 (for testing; 2021-04-09) diff --git a/README.md b/README.md index 8ebb10a..c000d83 100644 --- a/README.md +++ b/README.md @@ -66,6 +66,8 @@ to a JDBC library, such as [`next.jdbc`](https://github.com/seancorfield/next-jd (jdbc/execute! conn (sql/format sqlmap)) ``` +> Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you. + If you want to format the query as a string with no parameters (e.g. to use the SQL statement in a SQL console), pass `:inline true` as an option to `sql/format`: ```clojure @@ -73,9 +75,7 @@ If you want to format the query as a string with no parameters (e.g. to use the => ["SELECT a, b, c FROM foo WHERE f.a = 'baz'"] ``` -> Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you. - -Namespace-qualified keywords are generally treated as table-qualified columns: `:foo/bar` becomes `foo.bar`, except in contexts where that would be illegal (such as the list of columns in an `INSERT` statement). This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. +Namespace-qualified keywords (and symbols) are generally treated as table-qualified columns: `:foo/bar` becomes `foo.bar`, except in contexts where that would be illegal (such as the list of columns in an `INSERT` statement). This approach is likely to be more compatible with code that uses libraries like [`next.jdbc`](https://github.com/seancorfield/next-jdbc) and [`seql`](https://github.com/exoscale/seql), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc. ```clojure (def q-sqlmap {:select [:foo/a :foo/b :foo/c] @@ -91,6 +91,11 @@ Namespace-qualified keywords are generally treated as table-qualified columns: ` => ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"] ``` +Documentation for the entire data DSL can be found in the +[Clause Reference](doc/clause-reference.md), the +[Operator Reference](doc/operator-reference.md)], and the +[Special Syntax referenc](doc/special-syntax.md). + ### Vanilla SQL clause helpers For every single SQL clause supported by HoneySQL (as keywords or symbols @@ -130,6 +135,8 @@ If you want to replace a clause, you can `dissoc` the existing clause first, sin => ["SELECT * FROM foo WHERE (f.a = ?) AND (b > ?)" "baz" 10] ``` +> Note: the helpers always produce keywords so you can rely on `dissoc` with the desired keyword to remove. If you are building the data DSL "manually" and using symbols instead of keywords, you'll need to `dissoc` the symbol form instead. + `where` will combine multiple clauses together using SQL's `AND`: ```clojure @@ -160,6 +167,9 @@ functions interchangably. For any example using the helpers, you could evaluate it (without the call to `sql/format`) to see what the equivalent data structure would be. +Documentation for all the helpers can be found in the +[`honey.sql.helpers` API reference](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/api/honey.sql.helpers). + ### Inserts Inserts are supported in two patterns. diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 1edc6fb..0e91e49 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -2,7 +2,8 @@ This section lists all the SQL clauses that HoneySQL supports out of the box, in the order that they are -processed for formatting. +processed for formatting (except for some natural +grouping of related clauses). Clauses can be specified as keywords or symbols. Use `-` in the clause name where the formatted SQL would have diff --git a/doc/general-reference.md b/doc/general-reference.md index d331076..856f9ad 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -57,7 +57,7 @@ when quoting is in effect: ``` Finally, there are some contexts where only a SQL entity is accepted, rather than an -arbitrary SQL expression, so a string will be treated as a SQL entity and in such cases +arbitrary SQL expression, so a string will also be treated as a SQL entity and in such cases the entity name will always be quoted, dashes (`-`) will not be converted to underscores (`_`), and a slash (`/`) is not treated as separating a qualifier from the name, regardless of the `:dialect` or `:quoted` settings: @@ -98,8 +98,12 @@ these tuples: ;;=> ["(?, ?, ?)" 13 42 "foo"] ``` +There is also a `composite` helper function. + ## Other Sections Will Be Added! +As questions arise about the use of HoneySQL 2.x, I will add new sections here. + ## Other Reference Documentation The full list of supported SQL clauses is documented in the diff --git a/doc/getting-started.md b/doc/getting-started.md index 2ad2ce8..86ad0a2 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -169,9 +169,9 @@ call as the `:params` key of the options hash map. ## Functional Helpers In addition to the hash map (and sequences) approach of building -SQL queries with raw Clojure data structures, a namespace full -of helper functions is also available. These functions are -generally variadic and threadable: +SQL queries with raw Clojure data structures, a +[namespace full of helper functions](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/api/honey.sql.helpers) +is also available. These functions are generally variadic and threadable: ```clojure (ns my.example @@ -189,7 +189,7 @@ generally variadic and threadable: There is a helper function for every single clause that HoneySQL supports out of the box. In addition, there are helpers for `composite`, `lateral`, `over`, and `upsert` that make it easier to construct those -parts of the SQL DSL (examples of `composite` appear in the [README](README.md), +parts of the SQL DSL (examples of `composite` appear in the [README](/README.md), examples of `over` appear in the [Clause Reference](clause-reference.md)) In addition to being variadic -- which often lets you omit one @@ -231,7 +231,8 @@ you need to consider this when referring symbols in from the ## DDL Statements HoneySQL 1.x did not support any DDL statements. It was fairly -common for people to use the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) +common for people to use the +[nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) to get DDL support, even if they didn't need the PostgreSQL-specific extensions. That library does not work with HoneySQL 2.x but all of the functionality from it (up to 0.3.104) has been incorporated @@ -239,6 +240,9 @@ into HoneySQL now and is described in the [PostgreSQL](postgresql.md) section (because that covers all of the things that the nilenso library supported and much of it was PostgreSQL-specific!). +See also the [DDL Clauses section](clause-reference.md#ddl-clauses) of +the Clause Reference for documentation about supported DDL. + ## Dialects By default, HoneySQL operates in ANSI SQL mode but it supports @@ -308,6 +312,11 @@ was wrapped in `[:inline `..`]`: * keywords and symbols become SQL keywords (uppercase, with `-` replaced by a space), * everything else is just turned into a string (by calling `str`) and added to the SQL string. +`format` accepts options as either a single hash map argument or +as named arguments (alternating keys and values). If you are using +Clojure 1.11 (or later) you can mix'n'match, providing some options +as named arguments followed by other options in a hash map. + ## Reference Documentation The full list of supported SQL clauses is documented in the diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 12b951e..1e396d3 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -1206,7 +1206,12 @@ any parameter values that were encountered in the DSL structure. This is the primary API for HoneySQL and handles dialects, quoting, - and named parameters." + and named parameters. + + `format` accepts options as either a single hash map argument or + as named arguments (alternating keys and values). If you are using + Clojure 1.11 (or later) you can mix'n'match, providing some options + as named arguments followed by other options in a hash map." ([data] (format data {})) ([data opts] (let [dialect? (contains? opts :dialect) From 50fd829752c7e75738d30e6eb031c35d77074af0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 14:32:48 -0700 Subject: [PATCH 229/254] Addresses #310 by adding filter, order-by, within-group syntax --- README.md | 8 ++-- doc/getting-started.md | 2 +- doc/special-syntax.md | 63 ++++++++++++++++++++++++++++++++ src/honey/sql.cljc | 25 ++++++++++++- src/honey/sql/helpers.cljc | 31 ++++++++++++++-- test/honey/sql/helpers_test.cljc | 34 +++++++++++++++-- 6 files changed, 151 insertions(+), 12 deletions(-) diff --git a/README.md b/README.md index c000d83..bb4b356 100644 --- a/README.md +++ b/README.md @@ -24,10 +24,12 @@ Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty tr ## Usage ```clojure -(refer-clojure :exclude '[for group-by into partition-by set update]) +(refer-clojure :exclude '[filter for group-by into partition-by set update]) (require '[honey.sql :as sql] - ;; caution: this overwrites several clojure.core fns: - ;; for, group-by, into, partition-by, set, and update + ;; CAUTION: this overwrites several clojure.core fns: + ;; + ;; filter, for, group-by, into, partition-by, set, and update + ;; ;; you should generally only refer in the specific ;; helpers that you want to use! '[honey.sql.helpers :refer :all :as h] diff --git a/doc/getting-started.md b/doc/getting-started.md index 86ad0a2..9353745 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -225,7 +225,7 @@ can rely on using keywords in `dissoc`. The following helpers shadow functions in `clojure.core` so you need to consider this when referring symbols in from the -`honey.sql.helpers` namespace: `for`, `group-by`, `into`, `partition-by`, +`honey.sql.helpers` namespace: `filter`, `for`, `group-by`, `into`, `partition-by`, `set`, and `update`. ## DDL Statements diff --git a/doc/special-syntax.md b/doc/special-syntax.md index afce294..04ab495 100644 --- a/doc/special-syntax.md +++ b/doc/special-syntax.md @@ -85,6 +85,46 @@ specify the escape characters (if any). ;;=> ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"])))) ``` +## filter, within-group + +Used to produce PostgreSQL's `FILTER` and `WITHIN GROUP` expressions. +See also **order-by** below. + +These both accept a SQL expression followed by a SQL clause. +Filter generally expects an aggregate expression and a `WHERE` clause. +Within group generally expects an aggregate expression and an `ORDER BY` clause. + +```clojure +(format {:select [:a :b [[:filter :%count.* {:where [:< :x 100]}] :c] + [[:within-group [:percentile_disc [:inline 0.25]] + {:order-by [:a]}] :inter_max] + [[:within-group [:percentile_cont [:inline 0.25]] + {:order-by [:a]}] :abs_max]] + :from :aa}) +;; newlines added for readability: +;;=> ["SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, +;;=> PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, +;;=> PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max +;;=> FROM aa" 100] +``` + +There are helpers for both `filter` and `within-group`. Be careful with `filter` +since it shadows `clojure.core/filter`: + +```clojure +(format (-> (select :a :b [(filter :%count.* (where :< :x 100)) :c] + [(within-group [:percentile_disc [:inline 0.25]] + (order-by :a)) :inter_max] + [(within-group [:percentile_cont [:inline 0.25]] + (order-by :a)) :abs_max]) + (from :aa))) +;; newlines added for readability: +;;=> ["SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, +;;=> PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, +;;=> PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max +;;=> FROM aa" 100] +``` + ## inline Accepts a single argument and tries to render it as a @@ -157,6 +197,29 @@ in front of it: ;;=> ["NOT x = ?" 42] ``` +## order-by + +In addition to the `ORDER BY` clause, HoneySQL also supports `ORDER BY` +in an expression (for PostgreSQL). It accepts a SQL expression followed +by an ordering specifier, which can be an expression or a pair of expression +and direction (`:asc` or `:desc`): + +```clojure +(format {:select [[[:array_agg [:order-by :a [:b :desc]]]]] :from :table}) +;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"] +(format (-> (select [[:array_agg [:order-by :a [:b :desc]]]]) + (from :table))) +;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"] +(format {:select [[[:string_agg :a [:order-by [:inline ","] :a]]]] :from :table}) +;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"] +(format (-> (select [[:string_agg :a [:order-by [:inline ","] :a]]]) + (from :table))) +;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"] +``` + +There is no helper for the `ORDER BY` special syntax: the `order-by` helper +only produces a SQL clause. + ## over This is intended to be used with the `:window` and `:partition-by` clauses. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1e396d3..26fa5ac 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -983,6 +983,20 @@ args)) ")")))))]) +(defn- expr-clause-pairs + "For FILTER and WITHIN GROUP that have an expression + followed by a SQL clause." + [k pairs] + (let [[sqls params] + (reduce (fn [[sqls params] [e c]] + (let [[sql-e & params-e] (format-expr e) + [sql-c & params-c] (format-dsl c {:nested true})] + [(conj sqls (str sql-e " " (sql-kw k) " " sql-c)) + (-> params (into params-e) (into params-c))])) + [[] []] + (partition 2 pairs))] + (into [(str/join ", " sqls)] params))) + (def ^:private special-syntax (atom {;; these "functions" are mostly used in column @@ -1054,6 +1068,7 @@ (-> [(str sql-p " " (sql-kw :escape) " " sql-e)] (into params-p) (into params-e)))) + :filter expr-clause-pairs :inline (fn [_ [x]] (if (sequential? x) @@ -1086,6 +1101,13 @@ (fn [_ [x]] (let [[sql & params] (format-expr x)] (into [(str "NOT " sql)] params))) + :order-by + (fn [k [e q]] + (let [[sql-e & params-e] (format-expr e) + [sql-q & params-q] (format-dsl {k [q]})] + (-> [(str sql-e " " sql-q)] + (into params-e) + (into params-q)))) :over (fn [_ [& args]] (let [[sqls params] @@ -1107,7 +1129,8 @@ ["?" (->param k)])) :raw (fn [_ [xs]] - (raw-render xs))})) + (raw-render xs)) + :within-group expr-clause-pairs})) (defn format-expr "Given a data structure that represents a SQL expression and a hash diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 5a1832f..ae56ab2 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -2,7 +2,7 @@ (ns honey.sql.helpers "Helper functions for the built-in clauses in honey.sql." - (:refer-clojure :exclude [for group-by into partition-by set update]) + (:refer-clojure :exclude [filter for group-by into partition-by set update]) (:require [clojure.core :as c] [honey.sql])) @@ -818,6 +818,18 @@ [& args] (c/into [:composite] args)) +(defn filter + "Accepts alternating expressions and clauses and + produces a FILTER expression: + + (filter :%count.* (where :> i 5)) + + Produces: COUNT(*) FILTER (WHERE i > ?) + Parameters: 5" + {:arglists '([expr1 clause1 & more])} + [& args] + (c/into [:filter] args)) + (defn lateral "Accepts a SQL clause or a SQL expression: @@ -844,6 +856,18 @@ [& args] [(c/into [:over] args)]) +(defn within-group + "Accepts alternating expressions and clauses and + produces a WITHIN GROUP expression: + + (within-group :%count.* (where :> i 5)) + + Produces: COUNT(*) WITHIN GROUP (WHERE i > ?) + Parameters: 5" + {:arglists '([expr1 clause1 & more])} + [& args] + (c/into [:within-group] args)) + ;; this helper is intended to ease the migration from nilenso: (defn upsert "Provided purely to ease migration from nilenso/honeysql-postgres @@ -898,9 +922,10 @@ #?(:clj (do ;; ensure #295 stays true (all public functions have docstring): - (assert (empty? (->> (ns-publics *ns*) (vals) (filter (comp not :doc meta))))) + (assert (empty? (->> (ns-publics *ns*) (vals) (c/filter (comp not :doc meta))))) ;; ensure all public functions match clauses: (assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order - :composite :lateral :over :upsert)) + :composite :filter :lateral :over :within-group + :upsert)) (clojure.core/set (conj (map keyword (keys (ns-publics *ns*))) :nest :raw)))))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index b69599f..c71696e 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -1,7 +1,7 @@ ;; copyright (c) 2020-2021 sean corfield, all rights reserved (ns honey.sql.helpers-test - (:refer-clojure :exclude [update set group-by for partition-by]) + (:refer-clojure :exclude [filter for group-by partition-by set update]) (:require #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sql] @@ -9,7 +9,8 @@ :refer [add-column add-index alter-table columns create-table create-table-as create-view create-materialized-view drop-view drop-materialized-view bulk-collect-into - cross-join do-update-set drop-column drop-index drop-table from full-join + cross-join do-update-set drop-column drop-index drop-table + filter from full-join group-by having insert-into join-by join lateral left-join limit offset on-conflict on-duplicate-key-update @@ -17,7 +18,7 @@ rename-column rename-table returning right-join select select-distinct select-top select-distinct-top values where window with with-columns - with-data]])) + with-data within-group]])) (deftest test-select (testing "large helper expression" @@ -844,4 +845,29 @@ (values [[42]]) (on-duplicate-key-update {:c1 [:+ [:values :c1] 1]}))) ["INSERT INTO table (c1) VALUES (?) ON DUPLICATE KEY UPDATE c1 = VALUES(c1) + ?" - 42 1])))) \ No newline at end of file + 42 1])))) + +(deftest filter-within-order-by-test + (testing "PostgreSQL filter, within group, order-by as special syntax" + (is (= (sql/format {:select [[[:filter :%count.* {:where [:> :i 5]}] :a] + [[:filter ; two pairs -- alias is on last pair + [:avg :x [:order-by :y [:a :desc]]] {:where [:< :i 10]} + [:sum :q] {:where [:= :x nil]}] :b] + [[:within-group [:foo :y] {:order-by [:x]}]]]}) + [(str "SELECT COUNT(*) FILTER (WHERE i > ?) AS a," + " AVG(x, y ORDER BY a DESC) FILTER (WHERE i < ?)," + " SUM(q) FILTER (WHERE x IS NULL) AS b," + " FOO(y) WITHIN GROUP (ORDER BY x ASC)") + 5 10]))) + (testing "PostgreSQL filter, within group, order-by as helpers" + (is (= (sql/format (select [(filter :%count.* (where :> :i 5)) :a] + [(filter ; two pairs -- alias is on last pair + ;; order by must remain special syntax here: + [:avg :x [:order-by :y [:a :desc]]] (where :< :i 10) + [:sum :q] (where := :x nil)) :b] + [(within-group [:foo :y] (order-by :x))])) + [(str "SELECT COUNT(*) FILTER (WHERE i > ?) AS a," + " AVG(x, y ORDER BY a DESC) FILTER (WHERE i < ?)," + " SUM(q) FILTER (WHERE x IS NULL) AS b," + " FOO(y) WITHIN GROUP (ORDER BY x ASC)") + 5 10])))) From bb9d196e3e91a16bb269362f53a438c4f066bbb3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 03:14:23 -0700 Subject: [PATCH 230/254] Document nilenso catch up to 0.4.112 --- CHANGELOG.md | 5 +++-- doc/differences-from-1-x.md | 4 ++-- doc/getting-started.md | 4 ++-- doc/postgresql.md | 14 ++++++++++++-- 4 files changed, 19 insertions(+), 8 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 53fee80..eb00f3f 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,8 +1,9 @@ # Changes * 2.0.next in progress - * The documentation continues to be expanded and clarified in respond to feedback! + * The documentation continues to be expanded and clarified in response to feedback! * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. + * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). * 2.0.0-beta1 (for testing; 2021-04-09) * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). @@ -21,7 +22,7 @@ * Add tests to confirm #299 does not affect 2.x. * Fix #297 by adding both `SELECT .. INTO ..` and `SELECT .. BULK COLLECT INTO ..`. * Fix #295 by adding docstrings to all helper functions (and adding an assert to ensure it stays that way as more are added in future). - * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293, but see #310 for recent additions not yet incorporated). + * Confirm the whole of the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) is implemented out-of-the-box (#293, up to 0.3.104 -- see also #310 which brought parity up to 0.4.112). * Fix #292 by adding support for `SELECT TOP` and `OFFSET`/`FETCH`. * Fix #284 by adding support for `LATERAL` (as special syntax, with a helper). * Reconcile `where` behavior with recent 1.x changes (porting #283 to 2.x). diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index dd9a672..3cc0b45 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -140,7 +140,7 @@ On a related note, `sql/call` has been removed because it should never be needed ### select modifiers HoneySQL 1.x provided a `:modifiers` clause (and a `modifiers`) helper as a way to "modify" -a `SELECT` to be `DISTINCT`. nilenso/honeysql-helpers extended that to support `:distinct-on` +a `SELECT` to be `DISTINCT`. The [nilenso/honeysql-helpers](https://github.com/nilenso/honeysql-postgres) library extended that to support `:distinct-on` a group of columns. In HoneySQL 2.x, you use `:select-distinct` and `:select-distinct-on` (and their associated helpers) for that instead. MS SQL Server's `TOP` modifier is also supported via `:select-top` and `:select-distinct-top`. @@ -173,7 +173,7 @@ You can also register new "functions" that can implement special syntax (such as And, finally, you can register new operators that will be recognized in expressions via `honey.sql/register-op!`. This accepts an operator name as a keyword and optional named parameters to indicate whether the operator is `:variadic` (the default is strictly binary) and whether it should ignore operands that evaluate to `nil` (via `:ignore-nil`). The latter can make it easier to construct complex expressions programmatically without having to worry about conditionally removing "optional" (`nil`) values. -> Note: because of the changes in the extension machinery between 1.x and 2.x, it is not possible to use the https://github.com/nilenso/honeysql-postgres library with HoneySQL 2.x but the goal is to incorporate all of the syntax from that library into the core of HoneySQL. +> Note: because of the changes in the extension machinery between 1.x and 2.x, it is not possible to use the [nilenso/honeysql-postgress](https://github.com/nilenso/honeysql-postgres) library with HoneySQL 2.x but the goal is to incorporate all of the syntax from that library into the core of HoneySQL. ## Helpers diff --git a/doc/getting-started.md b/doc/getting-started.md index 9353745..3f6f39f 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -235,7 +235,7 @@ common for people to use the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) to get DDL support, even if they didn't need the PostgreSQL-specific extensions. That library does not work with HoneySQL 2.x but all -of the functionality from it (up to 0.3.104) has been incorporated +of the functionality from it (up to 0.4.112) has been incorporated into HoneySQL now and is described in the [PostgreSQL](postgresql.md) section (because that covers all of the things that the nilenso library supported and much of it was PostgreSQL-specific!). @@ -292,7 +292,7 @@ specify a dialect in the `format` call, you can specify Out of the box, as part of the extended ANSI SQL support, HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md). -> Note: the [nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres) which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library (up to 0.3.104) out of the box! +> Note: the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) library which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library (up to 0.4.112) out of the box! ## Format Options diff --git a/doc/postgresql.md b/doc/postgresql.md index 8b4ceff..ec48ae6 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -3,9 +3,10 @@ This section covers the PostgreSQL-specific features that HoneySQL supports out of the box for which you previously needed the -[nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres). +[nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) +library. -Everything that the nilenso library provided (in 0.3.104) is implemented +Everything that the nilenso library provided (in 0.4.112) is implemented directly in HoneySQL 2.x although a few things have a slightly different syntax. @@ -336,6 +337,15 @@ user=> (sql/format (alter-table :fruit ADD UNIQUE fruit_name(name)"] ``` +## Filter / Within Group + +`honeysql-postgres` added support for `FILTER` and `WITHIN GROUP` +in its 0.4.112 release. Those features have been integrated into +HoneySQL 2.x (as of 2.0.next), along with support for `ORDER BY` +in expressions. `:filter`, `:within-group`, and `:order-by` are +all available as "functions" in [Special Syntax](special-syntax.md), +and there are helpers for `filter` and `within-group`. + ## Window / Partition Support HoneySQL supports `:window`, `:partition-by`, and `:over` From d734767877b718244d366a7680069eb99ab723b3 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 03:21:35 -0700 Subject: [PATCH 231/254] Remove the old 1.x code It hasn't been part of the deployed library for quite a while because I had moved it into the test folder, while I was reaching parity. --- test/data_readers.clj | 6 - test/honeysql/core.cljc | 76 ---- test/honeysql/core_test.cljc | 270 ------------- test/honeysql/format.cljc | 714 --------------------------------- test/honeysql/format_test.cljc | 322 --------------- test/honeysql/helpers.cljc | 330 --------------- test/honeysql/types.cljc | 105 ----- test/honeysql/util.clj | 5 - 8 files changed, 1828 deletions(-) delete mode 100644 test/data_readers.clj delete mode 100644 test/honeysql/core.cljc delete mode 100644 test/honeysql/core_test.cljc delete mode 100644 test/honeysql/format.cljc delete mode 100644 test/honeysql/format_test.cljc delete mode 100644 test/honeysql/helpers.cljc delete mode 100644 test/honeysql/types.cljc delete mode 100644 test/honeysql/util.clj diff --git a/test/data_readers.clj b/test/data_readers.clj deleted file mode 100644 index 50eb769..0000000 --- a/test/data_readers.clj +++ /dev/null @@ -1,6 +0,0 @@ -{sql/call honeysql.types/read-sql-call - sql/inline honeysql.types/read-sql-inline - sql/raw honeysql.types/read-sql-raw - sql/param honeysql.types/read-sql-param - sql/array honeysql.types/read-sql-array - sql/regularize honeysql.format/regularize} diff --git a/test/honeysql/core.cljc b/test/honeysql/core.cljc deleted file mode 100644 index 8a2a144..0000000 --- a/test/honeysql/core.cljc +++ /dev/null @@ -1,76 +0,0 @@ -(ns honeysql.core - (:refer-clojure :exclude [group-by format]) - (:require [honeysql.format :as format] - [honeysql.types :as types] - [honeysql.helpers :refer [build-clause]] - #?(:clj [honeysql.util :refer [defalias]]) - [clojure.string :as string])) - -(#?(:clj defalias :cljs def) call types/call) -(#?(:clj defalias :cljs def) raw types/raw) -(#?(:clj defalias :cljs def) param types/param) -(#?(:clj defalias :cljs def) inline types/inline) -(#?(:clj defalias :cljs def) format format/format) -(#?(:clj defalias :cljs def) format-predicate format/format-predicate) -(#?(:clj defalias :cljs def) quote-identifier format/quote-identifier) - -(defn qualify - "Takes one or more keyword or string qualifers and name. Returns - a keyword of the concatenated qualifiers and name separated by periods. - - (qualify :foo \"bar\" :baz) => :foo.bar.baz" - [& qualifiers+name] - (keyword - (string/join "." - (for [s qualifiers+name - :when (not (nil? s))] - (if (keyword? s) - (name s) - (str s)))))) - -(defn build - "Takes a series of clause+data pairs and returns a SQL map. Example: - - (build :select [:a :b] - :from :bar) - - Clauses are defined with the honeysql.helpers/build-clause multimethod. - Built-in clauses include: - - :select, :merge-select, :un-select - :from, :merge-from - :join, :merge-join - :left-join, :merge-left-join - :right-join, :merge-right-join - :full-join, :merge-full-join - :cross-join, :merge-cross-join - :where, :merge-where - :group-by, :merge-group-by - :having, :merge-having - :limit - :offset - :modifiers, :merge-modifiers - :insert-into - :columns, :merge-columns - :values, :merge-values - :query-values - :update - :set - :delete-from" - [& clauses] - (let [[base clauses] (if (map? (first clauses)) - [(first clauses) (rest clauses)] - [{} clauses])] - (reduce - (fn [sql-map [op args]] - (build-clause op sql-map args)) - (if (empty? base) - base - (apply build (apply concat base))) - (partition 2 clauses)))) - -(comment - (require '[honeysql.core :as sql]) - (sql/format {:select [:*] :from [:table] :where [:= :id 1]}) - (sql/format {:select [:*] :from [:table] :where [:= :id 1]} :quoting :mysql) - ,) diff --git a/test/honeysql/core_test.cljc b/test/honeysql/core_test.cljc deleted file mode 100644 index 4247f1b..0000000 --- a/test/honeysql/core_test.cljc +++ /dev/null @@ -1,270 +0,0 @@ -(ns honeysql.core-test - (:refer-clojure :exclude [format update]) - (:require [#?@(:clj [clojure.test :refer] - :cljs [cljs.test :refer-macros]) [deftest testing is]] - [honeysql.core :as sql] - [honeysql.helpers :refer [select modifiers from join left-join - right-join full-join cross-join - where group having - order-by limit offset values columns - insert-into with merge-where]] - honeysql.format-test)) - -;; TODO: more tests - -(deftest test-select - (let [m1 (-> (with [:cte (-> (select :*) - (from :example) - (where [:= :example-column 0]))]) - (select :f.* :b.baz :c.quux [:b.bla :bla-bla] - :%now (sql/raw "@x := 10")) - ;;(un-select :c.quux) - (modifiers :distinct) - (from [:foo :f] [:baz :b]) - (join :draq [:= :f.b :draq.x]) - (left-join [:clod :c] [:= :f.a :c.d]) - (right-join :bock [:= :bock.z :c.e]) - (full-join :beck [:= :beck.x :c.y]) - (where [:or - [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] - [:between :f.e 10 20]]) - ;;(merge-where [:not= nil :b.bla]) - (group :f.a) - (having [:< 0 :f.e]) - (order-by [:b.baz :desc] :c.quux [:f.a :nulls-first]) - (limit 50) - (offset 10)) - m2 {:with [[:cte {:select [:*] - :from [:example] - :where [:= :example-column 0]}]] - :select [:f.* :b.baz :c.quux [:b.bla :bla-bla] - :%now (sql/raw "@x := 10")] - ;;:un-select :c.quux - :modifiers :distinct - :from [[:foo :f] [:baz :b]] - :join [:draq [:= :f.b :draq.x]] - :left-join [[:clod :c] [:= :f.a :c.d]] - :right-join [:bock [:= :bock.z :c.e]] - :full-join [:beck [:= :beck.x :c.y]] - :where [:or - [:and [:= :f.a "bort"] [:not= :b.baz :?param1]] - [:< 1 2 3] - [:in :f.e [1 (sql/param :param2) 3]] - [:between :f.e 10 20]] - ;;:merge-where [:not= nil :b.bla] - :group-by :f.a - :having [:< 0 :f.e] - :order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]] - :limit 50 - :offset 10} - m3 (sql/build m2) - m4 (apply sql/build (apply concat m2))] - (testing "Various construction methods are consistent" - (is (= m1 m3 m4))) - (testing "SQL data formats correctly" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? " - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format m1 {:param1 "gabba" :param2 2})))) - #?(:clj (testing "SQL data prints and reads correctly" - (is (= m1 (read-string (pr-str m1)))))) - (testing "SQL data formats correctly with alternate param naming" - (is (= (sql/format m1 :params {:param1 "gabba" :param2 2} :parameterizer :postgresql) - ["WITH cte AS (SELECT * FROM example WHERE example_column = $1) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = $2 AND b.baz <> $3) OR ($4 < $5 AND $6 < $7) OR (f.e in ($8, $9, $10)) OR f.e BETWEEN $11 AND $12) GROUP BY f.a HAVING $13 < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT $14 OFFSET $15 " - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]))) - (testing "Locking" - (is (= ["WITH cte AS (SELECT * FROM example WHERE example_column = ?) SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS bla_bla, now(), @x := 10 FROM foo f, baz b INNER JOIN draq ON f.b = draq.x LEFT JOIN clod c ON f.a = c.d RIGHT JOIN bock ON bock.z = c.e FULL JOIN beck ON beck.x = c.y WHERE ((f.a = ? AND b.baz <> ?) OR (? < ? AND ? < ?) OR (f.e in (?, ?, ?)) OR f.e BETWEEN ? AND ?) GROUP BY f.a HAVING ? < f.e ORDER BY b.baz DESC, c.quux, f.a NULLS FIRST LIMIT ? OFFSET ? FOR UPDATE " - 0 "bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10] - (sql/format (assoc m1 :lock {:mode :update}) - {:param1 "gabba" :param2 2})))))) - -(deftest test-cast - (is (= ["SELECT foo, CAST(bar AS integer)"] - (sql/format {:select [:foo (sql/call :cast :bar :integer)]}))) - (is (= ["SELECT foo, CAST(bar AS integer)"] - (sql/format {:select [:foo (sql/call :cast :bar 'integer)]})))) - -(deftest test-value - (is (= ["INSERT INTO foo (bar) VALUES (?)" {:baz "my-val"}] - (-> - (insert-into :foo) - (columns :bar) - (values [[(honeysql.format/value {:baz "my-val"})]]) - sql/format))) - (is (= ["INSERT INTO foo (a, b, c) VALUES (?, ?, ?), (?, ?, ?)" - "a" "b" "c" "a" "b" "c"] - (-> (insert-into :foo) - (values [(array-map :a "a" :b "b" :c "c") - (hash-map :a "a" :b "b" :c "c")]) - sql/format)))) - -(deftest test-operators - (testing "=" - (testing "with nil" - (is (= ["SELECT * FROM customers WHERE name IS NULL"] - (sql/format {:select [:*] - :from [:customers] - :where [:= :name nil]}))) - (is (= ["SELECT * FROM customers WHERE name = ?" nil] - (sql/format {:select [:*] - :from [:customers] - :where [:= :name :?name]} - {:name nil}))))) - (testing "in" - (doseq [[cname coll] [[:vector []] [:set #{}] [:list '()]]] - (testing (str "with values from a " (name cname)) - (let [values (conj coll 1)] - (is (= ["SELECT * FROM customers WHERE (id in (?))" 1] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE (id in (?))" 1] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:ids values})))))) - (testing "with more than one integer" - (let [values [1 2]] - (is (= ["SELECT * FROM customers WHERE (id in (?, ?))" 1 2] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE (id in (?, ?))" 1 2] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:ids values}))))) - (testing "with more than one string" - (let [values ["1" "2"]] - (is (= ["SELECT * FROM customers WHERE (id in (?, ?))" "1" "2"] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}) - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:ids values}))))))) - -(deftest test-case - (is (= ["SELECT CASE WHEN foo < ? THEN ? WHEN (foo > ? AND (foo mod ?) = ?) THEN (foo / ?) ELSE ? END FROM bar" - 0 -1 0 2 0 2 0] - (sql/format - {:select [(sql/call - :case - [:< :foo 0] -1 - [:and [:> :foo 0] [:= (sql/call :mod :foo 2) 0]] (sql/call :/ :foo 2) - :else 0)] - :from [:bar]}))) - (let [param1 1 - param2 2 - param3 "three"] - (is (= ["SELECT CASE WHEN foo = ? THEN ? WHEN foo = bar THEN ? WHEN bar = ? THEN (bar * ?) ELSE ? END FROM baz" - param1 0 param2 0 param3 "param4"] - (sql/format - {:select [(sql/call - :case - [:= :foo :?param1] 0 - [:= :foo :bar] (sql/param :param2) - [:= :bar 0] (sql/call :* :bar :?param3) - :else "param4")] - :from [:baz]} - {:param1 param1 - :param2 param2 - :param3 param3}))))) - -(deftest test-raw - (is (= ["SELECT 1 + 1 FROM foo"] - (-> (select (sql/raw "1 + 1")) - (from :foo) - sql/format)))) - -(deftest test-call - (is (= ["SELECT min(?) FROM ?" "time" "table"] - (-> (select (sql/call :min "time")) - (from "table") - sql/format)))) - -(deftest join-test - (testing "nil join" - (is (= ["SELECT * FROM foo INNER JOIN x ON foo.id = x.id INNER JOIN y"] - (-> (select :*) - (from :foo) - (join :x [:= :foo.id :x.id] :y nil) - sql/format))))) - -(deftest join-using-test - (testing "nil join" - (is (= ["SELECT * FROM foo INNER JOIN x USING (id) INNER JOIN y USING (foo, bar)"] - (-> (select :*) - (from :foo) - (join :x [:using :id] :y [:using :foo :bar]) - sql/format))))) - -(deftest inline-test - (is (= ["SELECT * FROM foo WHERE id = 5"] - (-> (select :*) - (from :foo) - (where [:= :id (sql/inline 5)]) - sql/format))) - ;; testing for = NULL always fails in SQL -- this test is just to show - ;; that an #inline nil should render as NULL (so make sure you only use - ;; it in contexts where a literal NULL is acceptable!) - (is (= ["SELECT * FROM foo WHERE id = NULL"] - (-> (select :*) - (from :foo) - (where [:= :id (sql/inline nil)]) - sql/format)))) - -(deftest merge-where-no-params-test - (testing "merge-where called with just the map as parameter - see #228" - (let [sqlmap (-> (select :*) - (from :table) - (where [:= :foo :bar]))] - (is (= ["SELECT * FROM table WHERE foo = bar"] - (sql/format (apply merge-where sqlmap []))))))) - -(deftest merge-where-test - (is (= ["SELECT * FROM table WHERE (foo = bar AND quuz = xyzzy)"] - (-> (select :*) - (from :table) - (where [:= :foo :bar] [:= :quuz :xyzzy]) - sql/format))) - (is (= ["SELECT * FROM table WHERE (foo = bar AND quuz = xyzzy)"] - (-> (select :*) - (from :table) - (where [:= :foo :bar]) - (merge-where [:= :quuz :xyzzy]) - sql/format)))) - -(deftest where-nil-params-test - (testing "where called with nil parameters - see #246" - (is (= ["SELECT * FROM table WHERE (foo = bar AND quuz = xyzzy)"] - (-> (select :*) - (from :table) - (where nil [:= :foo :bar] nil [:= :quuz :xyzzy] nil) - sql/format))) - (is (= ["SELECT * FROM table"] - (-> (select :*) - (from :table) - (where) - sql/format))) - (is (= ["SELECT * FROM table"] - (-> (select :*) - (from :table) - (where nil nil nil nil) - sql/format))))) - -(deftest cross-join-test - (is (= ["SELECT * FROM foo CROSS JOIN bar"] - (-> (select :*) - (from :foo) - (cross-join :bar) - sql/format))) - (is (= ["SELECT * FROM foo f CROSS JOIN bar b"] - (-> (select :*) - (from [:foo :f]) - (cross-join [:bar :b]) - sql/format)))) - -#?(:cljs (cljs.test/run-all-tests)) diff --git a/test/honeysql/format.cljc b/test/honeysql/format.cljc deleted file mode 100644 index 2eb9c43..0000000 --- a/test/honeysql/format.cljc +++ /dev/null @@ -1,714 +0,0 @@ -(ns honeysql.format - (:refer-clojure :exclude [format]) - (:require [honeysql.types :as types - :refer [call raw param param-name inline-str - #?@(:cljs [SqlCall SqlRaw SqlParam SqlArray SqlInline])]] - [clojure.string :as string]) - #?(:clj (:import [honeysql.types SqlCall SqlRaw SqlParam SqlArray SqlInline]))) - -;;(set! *warn-on-reflection* true) - -;;;; - -(defn comma-join [s] - (string/join ", " s)) - -(defn space-join [s] - (string/join " " s)) - -(defn paren-wrap [x] - (str "(" x ")")) - -(def ^:dynamic *clause* - "During formatting, *clause* is bound to :select, :from, :where, etc." - nil) - -(def ^:dynamic *params* - "Will be bound to an atom-vector that accumulates SQL parameters across - possibly-recursive function calls" - nil) - -(def ^:dynamic *param-names* nil) - -(def ^:dynamic *param-counter* nil) - -(def ^:dynamic *all-param-counter* nil) - -(def ^:dynamic *input-params* nil) - -(def ^:dynamic *fn-context?* false) - -(def ^:dynamic *value-context?* false) - -(def ^:dynamic *subquery?* false) - -(def ^:dynamic *allow-dashed-names?* false) - -(def ^:dynamic *allow-namespaced-names?* false) - -(def ^:dynamic *namespace-as-table?* false) - -(def ^:dynamic *name-transform-fn* nil) - -(def ^:private quote-fns - {:ansi #(str \" (string/replace % "\"" "\"\"") \") - :mysql #(str \` (string/replace % "`" "``") \`) - :sqlserver #(str \[ (string/replace % "]" "]]") \]) - :oracle #(str \" (string/replace % "\"" "\"\"") \")}) - - -(defmulti parameterize (fn [parameterizer & args] parameterizer)) - -(defmethod parameterize :postgresql [_ value pname] - (str "$" (swap! *all-param-counter* inc))) - -(defmethod parameterize :jdbc [_ value pname] - "?") - -(defmethod parameterize :none [_ value pname] - (str (last @*params*))) - - -(def ^:dynamic *quote-identifier-fn* nil) -(def ^:dynamic *parameterizer* nil) - -(defn- undasherize [s] - (string/replace s "-" "_")) - -;; String.toUpperCase() or `string/upper-case` for that matter converts the string to uppercase for the DEFAULT -;; LOCALE. Normally this does what you'd expect but things like `inner join` get converted to `İNNER JOIN` (dot over -;; the I) when user locale is Turkish. This predictably has bad consequences for people who like their SQL queries to -;; work. The fix here is to use String.toUpperCase(Locale/US) instead which always converts things the way we'd expect. -;; -;; Use this function instead of `string/upper-case` as it will always use Locale/US. -(def ^:private ^{:arglists '([s])} upper-case - ;; TODO - not sure if there's a JavaScript equivalent here we should be using as well - #?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US)))) - :cljs string/upper-case)) - -(defn quote-identifier [x & {:keys [style split] :or {split true}}] - (let [name-transform-fn (cond - *name-transform-fn* *name-transform-fn* - *allow-dashed-names?* identity - :else undasherize) - qf (if style - (quote-fns style) - *quote-identifier-fn*) - s (cond - (or (keyword? x) (symbol? x)) - (name-transform-fn - (cond *namespace-as-table?* - (str (when-let [n (namespace x)] - (str n ".")) - (name x)) - *allow-namespaced-names?* - (str (when-let [n (namespace x)] - (str n "/")) - (name x)) - :else - (name x))) - (string? x) (if qf x (name-transform-fn x)) - :else (str x))] - (if-not qf - s - (let [qf* #(if (= "*" %) % (qf %))] - (if-not split - (qf* s) - (let [parts (string/split s #"\.")] - (string/join "." (map qf* parts)))))))) - -(def infix-fns - #{"+" "-" "*" "/" "%" "mod" "|" "&" "^" - "and" "or" "xor" - "in" "not in" "like" "not like" "regexp"}) - -(def fn-aliases - {"is" "=" - "is-not" "<>" - "not=" "<>" - "!=" "<>" - "not-in" "not in" - "not-like" "not like" - "regex" "regexp"}) - -(defprotocol ToSql - (to-sql [x])) - -(defn to-sql-value [x] - (binding [*value-context?* (sequential? x)] - (to-sql x))) - -(defmulti fn-handler (fn [op & args] op)) - -(defn expand-binary-ops [op & args] - (str "(" - (string/join " AND " - (for [[a b] (partition 2 1 args)] - (fn-handler op a b))) - ")")) - -(defmethod fn-handler :default [op & args] - (let [args (map to-sql args)] - (if (infix-fns op) - (paren-wrap (string/join (str " " op " ") args)) - (str op (paren-wrap (comma-join args)))))) - -(defmethod fn-handler "count-distinct" [_ & args] - (str "COUNT(DISTINCT " (comma-join (map to-sql args)) ")")) - -(defmethod fn-handler "distinct-on" [_ & args] - (str "DISTINCT ON (" (comma-join (map to-sql args)) ")")) - -(defmethod fn-handler "cast" [_ field cast-to-type] - (str "CAST" (paren-wrap (str (to-sql field) - " AS " - (to-sql cast-to-type))))) - -(defmethod fn-handler "=" [_ a b & more] - (if (seq more) - (apply expand-binary-ops "=" a b more) - (cond - (nil? a) (str (to-sql-value b) " IS NULL") - (nil? b) (str (to-sql-value a) " IS NULL") - :else (str (to-sql-value a) " = " (to-sql-value b))))) - -(defmethod fn-handler "<>" [_ a b & more] - (if (seq more) - (apply expand-binary-ops "<>" a b more) - (cond - (nil? a) (str (to-sql-value b) " IS NOT NULL") - (nil? b) (str (to-sql-value a) " IS NOT NULL") - :else (str (to-sql-value a) " <> " (to-sql-value b))))) - -(defmethod fn-handler "<" [_ a b & more] - (if (seq more) - (apply expand-binary-ops "<" a b more) - (str (to-sql-value a) " < " (to-sql-value b)))) - -(defmethod fn-handler "<=" [_ a b & more] - (if (seq more) - (apply expand-binary-ops "<=" a b more) - (str (to-sql-value a) " <= " (to-sql-value b)))) - -(defmethod fn-handler ">" [_ a b & more] - (if (seq more) - (apply expand-binary-ops ">" a b more) - (str (to-sql-value a) " > " (to-sql-value b)))) - -(defmethod fn-handler ">=" [_ a b & more] - (if (seq more) - (apply expand-binary-ops ">=" a b more) - (str (to-sql-value a) " >= " (to-sql-value b)))) - -(defmethod fn-handler "between" [_ field lower upper] - (str (to-sql-value field) " BETWEEN " (to-sql-value lower) " AND " (to-sql-value upper))) - -;; Handles MySql's MATCH (field) AGAINST (pattern). The third argument -;; can be a set containing one or more of :boolean, :natural, or :expand. -(defmethod fn-handler "match" [_ fields pattern & [opts]] - (str "MATCH (" - (comma-join - (map to-sql (if (coll? fields) fields [fields]))) - ") AGAINST (" - (to-sql-value pattern) - (when (seq opts) - (str " " (space-join (for [opt opts] - (case opt - :boolean "IN BOOLEAN MODE" - :natural "IN NATURAL LANGUAGE MODE" - :expand "WITH QUERY EXPANSION"))))) - ")")) - -(def default-clause-priorities - "Determines the order that clauses will be placed within generated SQL" - {:with 20 - :with-recursive 30 - :intersect 35 - :union 40 - :union-all 45 - :except 47 - :select 50 - :insert-into 60 - :update 70 - :delete 75 - :delete-from 80 - :truncate 85 - :columns 90 - :composite 95 - :set0 100 ; low-priority set clause - :from 110 - :join 120 - :left-join 130 - :right-join 140 - :full-join 150 - :cross-join 152 - :set 155 - :set1 156 ; high-priority set clause (synonym for :set) - :where 160 - :group-by 170 - :having 180 - :order-by 190 - :limit 200 - :offset 210 - :lock 215 - :values 220 - :query-values 230}) - -(def clause-store (atom default-clause-priorities)) - -(defn register-clause! [clause-key priority] - (swap! clause-store assoc clause-key priority)) - -(defn sort-clauses [clauses] - (let [m @clause-store] - (sort-by - (fn [c] - (m c #?(:clj Long/MAX_VALUE :cljs js/Number.MAX_VALUE))) - clauses))) - -(defn format - "Takes a SQL map and optional input parameters and returns a vector - of a SQL string and parameters, as expected by `next.jbc` and - `clojure.java.jdbc`. - - Input parameters will be filled into designated spots according to - name (if a map is provided) or by position (if a sequence is provided). - - Instead of passing parameters, you can use keyword arguments: - :params - input parameters - :quoting - quote style to use for identifiers; one of :ansi (PostgreSQL), - :mysql, :sqlserver, or :oracle. Defaults to no quoting. - :parameterizer - style of parameter naming, :postgresql, - :jdbc or :none. Defaults to :jdbc. - :return-param-names - when true, returns a vector of - [sql-str param-values param-names]" - [sql-map & params-or-opts] - (let [opts (when (keyword? (first params-or-opts)) - (apply hash-map params-or-opts)) - params (if (coll? (first params-or-opts)) - (first params-or-opts) - (:params opts))] - (binding [*params* (atom []) - *param-counter* (atom 0) - *all-param-counter* (atom 0) - *param-names* (atom []) - *input-params* (atom params) - *quote-identifier-fn* (quote-fns (:quoting opts)) - *parameterizer* (or (:parameterizer opts) :jdbc) - *allow-dashed-names?* (:allow-dashed-names? opts) - *allow-namespaced-names?* (:allow-namespaced-names? opts) - *namespace-as-table?* (:namespace-as-table? opts)] - (let [sql-str (to-sql sql-map)] - (if (and (seq @*params*) (not= :none (:parameterizer opts))) - (if (:return-param-names opts) - [sql-str @*params* @*param-names*] - (into [sql-str] @*params*)) - [sql-str]))))) - -(defprotocol Parameterizable - (to-params [value pname])) - -(defn to-params-seq [s pname] - (paren-wrap (comma-join (mapv #(to-params % pname) s)))) - -(defn to-params-default [value pname] - (swap! *params* conj value) - (swap! *param-names* conj pname) - (parameterize *parameterizer* value pname)) - -(extend-protocol Parameterizable - #?@(:clj - [clojure.lang.Sequential - - (to-params [value pname] - (to-params-seq value pname))]) - #?(:clj clojure.lang.IPersistentSet - :cljs cljs.core/PersistentHashSet) - (to-params [value pname] - (to-params (seq value) pname)) - nil - (to-params [value pname] - (swap! *params* conj value) - (swap! *param-names* conj pname) - (parameterize *parameterizer* value pname)) - #?(:clj Object :cljs default) - (to-params [value pname] - #?(:clj - (to-params-default value pname) - :cljs - (if (sequential? value) - (to-params-seq value pname) - (to-params-default value pname))))) - -(defn add-param [pname pval] - (to-params pval pname)) - -;; Anonymous param name -- :_1, :_2, etc. -(defn add-anon-param [pval] - (add-param - (keyword (str "_" (swap! *param-counter* inc))) - pval)) - -(defrecord Value [v] - ToSql - (to-sql [_] - (add-anon-param v))) - -(defn value [x] (Value. x)) - -(declare -format-clause) - -(defn map->sql [m] - (let [clause-ops (sort-clauses (keys m)) - sql-str (binding [*subquery?* true - *fn-context?* false] - (space-join - (map (comp #(-format-clause % m) #(find m %)) - clause-ops)))] - (if *subquery?* - (paren-wrap sql-str) - sql-str))) - -(declare format-predicate*) - -(defn seq->sql [x] - (cond - *value-context?* - ;; sequences are operators/functions - (format-predicate* x) - *fn-context?* - ;; list argument in fn call - (paren-wrap (comma-join (map to-sql x))) - :else - ;; alias - (do - (assert (= 2 (count x)) (str "Alias should have two parts" x)) - (let [[target alias] x] - (str (to-sql target) - ; Omit AS in FROM, JOIN, etc. - Oracle doesn't allow it - (if (= :select *clause*) " AS " " ") - (if (or (string? alias) (keyword? alias) (symbol? alias)) - (quote-identifier alias :split false) - (binding [*subquery?* false] - (to-sql alias)))))))) - -(extend-protocol types/Inlinable - #?(:clj clojure.lang.Keyword - :cljs cljs.core/Keyword) - (inline-str [x] - (name x)) - nil - (inline-str [_] - "NULL") - #?(:clj Object :cljs default) - (inline-str [x] - (str x))) - -(extend-protocol ToSql - #?(:clj clojure.lang.Keyword - :cljs cljs.core/Keyword) - (to-sql [x] - (let [s (name x)] - (case (.charAt s 0) - \% (let [call-args (string/split (subs s 1) #"\." 2)] - (to-sql (apply call (map keyword call-args)))) - \? (to-sql (param (keyword (subs s 1)))) - (quote-identifier x)))) - #?(:clj clojure.lang.Symbol - :cljs cljs.core/Symbol) - (to-sql [x] (quote-identifier x)) - #?(:clj java.lang.Boolean :cljs boolean) - (to-sql [x] - (if x "TRUE" "FALSE")) - #?@(:clj - [clojure.lang.Sequential - (to-sql [x] (seq->sql x))]) - SqlCall - (to-sql [x] - (binding [*fn-context?* true] - (let [fn-name (name (.-name x)) - fn-name (fn-aliases fn-name fn-name)] - (apply fn-handler fn-name (.-args x))))) - SqlRaw - (to-sql [x] - (let [s (.-s x)] - (if (vector? s) - (string/join "" (map (fn [x] (if (string? x) x (to-sql x))) s)) - s))) - #?(:clj clojure.lang.IPersistentMap - :cljs cljs.core/PersistentArrayMap) - (to-sql [x] - (map->sql x)) - #?(:clj clojure.lang.IPersistentSet - :cljs cljs.core/PersistentHashSet) - (to-sql [x] - (to-sql (seq x))) - nil - (to-sql [x] "NULL") - SqlParam - (to-sql [x] - (let [pname (param-name x)] - (if (map? @*input-params*) - (add-param pname (get @*input-params* pname)) - (let [x (first @*input-params*)] - (swap! *input-params* rest) - (add-param pname x))))) - SqlArray - (to-sql [x] - (str "ARRAY[" (comma-join (map to-sql (.-values x))) "]")) - SqlInline - (to-sql [x] - (inline-str (.-value x))) - #?(:clj Object :cljs default) - (to-sql [x] - #?(:clj (add-anon-param x) - :cljs (if (sequential? x) - (seq->sql x) - (add-anon-param x)))) - #?@(:cljs - [cljs.core/PersistentHashMap - (to-sql [x] (map->sql x))])) - -(defn sqlable? [x] - (satisfies? ToSql x)) - -;;;; - -(defn format-predicate* [pred] - (if-not (sequential? pred) - (to-sql pred) - (let [[op & args] pred - op-name (name op)] - (case op-name - "not" (str "NOT " (format-predicate* (first args))) - - ("and" "or" "xor") - (->> args - (remove nil?) - (map format-predicate*) - (string/join (str " " (upper-case op-name) " ")) - (paren-wrap)) - - "exists" - (str "EXISTS " (to-sql (first args))) - - (to-sql (apply call pred)))))) - -(defn format-predicate - "Formats a predicate (e.g., for WHERE, JOIN, or HAVING) as a string." - [pred & {:keys [quoting parameterizer] - :or {parameterizer :jdbc}}] - (binding [*params* (atom []) - *param-counter* (atom 0) - *param-names* (atom []) - *quote-identifier-fn* (or (quote-fns quoting) - *quote-identifier-fn*) - *parameterizer* parameterizer] - (let [sql-str (format-predicate* pred)] - (if (seq @*params*) - (into [sql-str] @*params*) - [sql-str])))) - -(defmulti format-clause - "Takes a map entry representing a clause and returns an SQL string" - (fn [clause _] (key clause))) - -(defn- -format-clause - [clause _] - (binding [*clause* (key clause)] - (format-clause clause _))) - -(defmethod format-clause :default [& _] - "") - -(defmethod format-clause :exists [[_ table-expr] _] - (str "EXISTS " (to-sql table-expr))) - -(defmulti format-modifiers (fn [[op & _]] op)) - -(defmethod format-modifiers :distinct [_] "DISTINCT") - -(defmethod format-modifiers :default [coll] - (space-join (map (comp upper-case name) coll))) - -(defmethod format-clause :select [[_ fields] sql-map] - (str "SELECT " - (when (:modifiers sql-map) - (str (format-modifiers (:modifiers sql-map)) " ")) - (comma-join (map to-sql fields)))) - -(defmethod format-clause :from [[_ tables] _] - (str "FROM " (comma-join (map to-sql tables)))) - -(defmethod format-clause :where [[_ pred] _] - (str "WHERE " (format-predicate* pred))) - -(defn format-join [type table pred] - (str (when type - (str (upper-case (name type)) " ")) - "JOIN " (to-sql table) - (when (some? pred) - (if (and (sequential? pred) (= :using (first pred))) - (str " USING (" (->> pred rest (map quote-identifier) comma-join) ")") - (str " ON " (format-predicate* pred)))))) - -(defmethod format-clause :join [[_ join-groups] _] - (space-join (map #(apply format-join :inner %) - (partition 2 join-groups)))) - -(defmethod format-clause :left-join [[_ join-groups] _] - (space-join (map #(apply format-join :left %) - (partition 2 join-groups)))) - -(defmethod format-clause :right-join [[_ join-groups] _] - (space-join (map #(apply format-join :right %) - (partition 2 join-groups)))) - -(defmethod format-clause :full-join [[_ join-groups] _] - (space-join (map #(apply format-join :full %) - (partition 2 join-groups)))) - -(defmethod format-clause :cross-join [[_ join-groups] _] - (space-join (map #(format-join :cross % nil) join-groups))) - -(defmethod format-clause :group-by [[_ fields] _] - (str "GROUP BY " (comma-join (map to-sql fields)))) - -(defmethod format-clause :having [[_ pred] _] - (str "HAVING " (format-predicate* pred))) - -(defmethod format-clause :order-by [[_ fields] _] - (str "ORDER BY " - (comma-join (for [field fields] - (if (sequential? field) - (let [[field & modifiers] field] - (string/join " " - (cons (to-sql field) - (for [modifier modifiers] - (case modifier - :desc "DESC" - :asc "ASC" - :nulls-first "NULLS FIRST" - :nulls-last "NULLS LAST" - ""))))) - (to-sql field)))))) - -(defmethod format-clause :limit [[_ limit] _] - (str "LIMIT " (to-sql limit))) - -(defmethod format-clause :offset [[_ offset] _] - (str "OFFSET " (to-sql offset))) - -(defmulti format-lock-clause identity) - -(defmethod format-lock-clause :update [_] - "FOR UPDATE") - -(defmethod format-lock-clause :mysql-share [_] - "LOCK IN SHARE MODE") - -(defmethod format-lock-clause :postgresql-share [_] - "FOR SHARE") - -(defmethod format-clause :lock [[_ lock] _] - (let [{:keys [mode wait]} lock - clause (format-lock-clause mode)] - (str clause (when (false? wait) " NOWAIT")))) - -(defmethod format-clause :insert-into [[_ table] _] - (if (and (sequential? table) (sequential? (first table))) - (str "INSERT INTO " - (to-sql (ffirst table)) - (binding [*namespace-as-table?* false] - (str " (" (comma-join (map to-sql (second (first table)))) ") ")) - (binding [*subquery?* false] - (to-sql (second table)))) - (str "INSERT INTO " (to-sql table)))) - -(defmethod format-clause :columns [[_ fields] _] - (binding [*namespace-as-table?* false] - (str "(" (comma-join (map to-sql fields)) ")"))) - -(defmethod format-clause :composite [[_ fields] _] - (comma-join (map to-sql fields))) - -(defmethod format-clause :values [[_ values] _] - (if (sequential? (first values)) - (str "VALUES " (comma-join (for [x values] - (str "(" (comma-join (map to-sql x)) ")")))) - (let [cols (keys (first values))] - (str - (binding [*namespace-as-table?* false] - (str "(" (comma-join (map to-sql cols)) ")")) - " VALUES " - (comma-join (for [x values] - (str "(" (comma-join (map #(to-sql (get x %)) cols)) ")"))))))) - -(defmethod format-clause :query-values [[_ query-values] _] - (to-sql query-values)) - -(defmethod format-clause :update [[_ table] _] - (str "UPDATE " (to-sql table))) - -(defmethod format-clause :set [[_ values] _] - (str "SET " (comma-join (for [[k v] values] - (str (to-sql k) " = " (to-sql v)))))) - -(defmethod format-clause :set0 [[_ values] _] - (str "SET " (comma-join (for [[k v] values] - (str (to-sql k) " = " (to-sql v)))))) - -(defmethod format-clause :set1 [[_ values] _] - (str "SET " (comma-join (for [[k v] values] - (str (to-sql k) " = " (to-sql v)))))) - -(defmethod format-clause :delete-from [[_ table] _] - (str "DELETE FROM " (to-sql table))) - -(defmethod format-clause :delete [[_ tables] _] - (str "DELETE " (comma-join (map to-sql tables)))) - -(defmethod format-clause :truncate [[_ table] _] - (str "TRUNCATE " (to-sql table))) - -(defn cte->sql - [[cte-name query]] - (str (binding [*subquery?* false] - (to-sql cte-name)) - " AS " - (to-sql query))) - -(defmethod format-clause :with [[_ ctes] _] - (str "WITH " (comma-join (map cte->sql ctes)))) - -(defmethod format-clause :with-recursive [[_ ctes] _] - (str "WITH RECURSIVE " (comma-join (map cte->sql ctes)))) - -(defmethod format-clause :union [[_ maps] _] - (binding [*subquery?* false] - (string/join " UNION " (map to-sql maps)))) - -(defmethod format-clause :union-all [[_ maps] _] - (binding [*subquery?* false] - (string/join " UNION ALL " (map to-sql maps)))) - -(defmethod format-clause :intersect [[_ maps] _] - (binding [*subquery?* false] - (string/join " INTERSECT " (map to-sql maps)))) - -(defmethod format-clause :except [[_ maps] _] - (binding [*subquery?* false] - (string/join " EXCEPT " (map to-sql maps)))) - -(defmethod fn-handler "case" [_ & clauses] - (str "CASE " - (space-join - (for [[condition result] (partition 2 clauses)] - (if (= :else condition) - (str "ELSE " (to-sql result)) - (let [pred (format-predicate* condition)] - (str "WHEN " pred " THEN " (to-sql result)))))) - " END")) - -(defn regularize [sql-string] - (string/replace sql-string #"\s+" " ")) diff --git a/test/honeysql/format_test.cljc b/test/honeysql/format_test.cljc deleted file mode 100644 index d7fa8c7..0000000 --- a/test/honeysql/format_test.cljc +++ /dev/null @@ -1,322 +0,0 @@ -(ns honeysql.format-test - (:refer-clojure :exclude [format]) - (:require [#?@(:clj [clojure.test :refer] - :cljs [cljs.test :refer-macros]) [deftest testing is are]] - honeysql.core - [honeysql.types :as sql] - [honeysql.format :refer - [*allow-dashed-names?* *allow-namespaced-names?* - *namespace-as-table?* - quote-identifier format-clause format - parameterize]])) - -(deftest test-quote - (are - [qx res] - (= (apply quote-identifier "foo.bar.baz" qx) res) - [] "foo.bar.baz" - [:style :mysql] "`foo`.`bar`.`baz`" - [:style :mysql :split false] "`foo.bar.baz`") - (are - [x res] - (= (quote-identifier x) res) - 3 "3" - 'foo "foo" - :foo-bar "foo_bar") - (is (= (quote-identifier "*" :style :ansi) "*")) - (is (= (quote-identifier "foo\"bar" :style :ansi) "\"foo\"\"bar\"")) - (is (= (quote-identifier "foo\"bar" :style :oracle) "\"foo\"\"bar\"")) - (is (= (quote-identifier "foo`bar" :style :mysql) "`foo``bar`")) - (is (= (quote-identifier "foo]bar" :style :sqlserver) "[foo]]bar]"))) - -(deftest test-dashed-quote - (binding [*allow-dashed-names?* true] - (is (= (quote-identifier :foo-bar) "foo-bar")) - (is (= (quote-identifier :foo-bar :style :ansi) "\"foo-bar\"")) - (is (= (quote-identifier :foo-bar.moo-bar :style :ansi) - "\"foo-bar\".\"moo-bar\"")))) - -(deftest test-namespaced-identifier - (is (= (quote-identifier :foo/bar) "bar")) - (is (= (quote-identifier :foo/bar :style :ansi) "\"bar\"")) - (binding [*namespace-as-table?* true] - (is (= (quote-identifier :foo/bar) "foo.bar")) - (is (= (quote-identifier :foo/bar :style :ansi) "\"foo\".\"bar\"")) - (is (= (quote-identifier :foo/bar :style :ansi :split false) "\"foo.bar\""))) - (binding [*allow-namespaced-names?* true] - (is (= (quote-identifier :foo/bar) "foo/bar")) - (is (= (quote-identifier :foo/bar :style :ansi) "\"foo/bar\"")))) - -(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]]} - :quoting :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-clause - (first {:with [[:query {:select [:foo] :from [:bar]}]]}) nil) - "WITH query AS SELECT foo FROM bar")) - (is (= (format-clause - (first {:with-recursive [[:query {:select [:foo] :from [:bar]}]]}) nil) - "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-clause (first {:insert-into :foo}) nil) - "INSERT INTO foo")) - (is (= (format-clause (first {:insert-into [:foo {:select [:bar] :from [:baz]}]}) nil) - "INSERT INTO foo SELECT bar FROM baz")) - (is (= (format-clause (first {:insert-into [[:foo [:a :b :c]] {:select [:d :e :f] :from [:baz]}]}) nil) - "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 - (is (= (format {:insert-into :foo - :columns [:baz] - :values [[(sql/array [1 2 3 4])]]}) - ["INSERT INTO foo (baz) VALUES (ARRAY[?, ?, ?, ?])" 1 2 3 4])) - (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" - (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 :quoting :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 :quoting :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 :quoting :mysql))))) - -(deftest delete-from-test - (is (= ["DELETE FROM `foo` WHERE `foo`.`id` = ?" 42] - (-> {:delete-from :foo - :where [:= :foo.id 42]} - (format :quoting :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 :quoting :mysql))))) - -(deftest truncate-test - (is (= ["TRUNCATE `foo`"] - (-> {:truncate :foo} - (format :quoting :mysql))))) - -(deftest inlined-values-are-stringified-correctly - (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]]})))) diff --git a/test/honeysql/helpers.cljc b/test/honeysql/helpers.cljc deleted file mode 100644 index 5b5854c..0000000 --- a/test/honeysql/helpers.cljc +++ /dev/null @@ -1,330 +0,0 @@ -(ns honeysql.helpers - (:refer-clojure :exclude [update]) - #?(:cljs (:require-macros [honeysql.helpers :refer [defhelper]]))) - -(defmulti build-clause (fn [name & args] - name)) - -(defmethod build-clause :default [_ m & args] - m) - -(defn plain-map? [m] - (and - (map? m) - (not (record? m)))) - -#?(:clj - (defmacro defhelper [helper arglist & more] - (when-not (vector? arglist) - (throw #?(:clj (IllegalArgumentException. "arglist must be a vector") - :cljs (js/Error. "arglist must be a vector")))) - (when-not (= (count arglist) 2) - (throw #?(:clj (IllegalArgumentException. "arglist must have two entries, map and varargs") - :cljs (js/Error. "arglist must have two entries, map and varargs")))) - - (let [kw (keyword (name helper)) - [m-arg varargs] arglist] - `(do - (defmethod build-clause ~kw ~['_ m-arg varargs] ~@more) - (defn ~helper [& args#] - (let [[m# args#] (if (plain-map? (first args#)) - [(first args#) (rest args#)] - [{} args#])] - (build-clause ~kw m# args#))) - - ;; maintain the original arglist instead of getting - ;; ([& args__6880__auto__]) - (alter-meta! - (var ~helper) - assoc - :arglists - '(~['& varargs] - ~[m-arg '& varargs])))))) - -(defn collify [x] - (if (coll? x) x [x])) - -(defhelper select [m fields] - (assoc m :select (collify fields))) - -(defhelper merge-select [m fields] - (update-in m [:select] concat (collify fields))) - -(defhelper un-select [m fields] - (update-in m [:select] #(remove (set (collify fields)) %))) - -(defhelper from [m tables] - (assoc m :from (collify tables))) - -(defhelper merge-from [m tables] - (update-in m [:from] concat (collify tables))) - -(defmethod build-clause :where [_ m pred] - (if (nil? pred) - m - (assoc m :where pred))) - -(defn- prep-where [args] - (let [[m preds] (if (map? (first args)) - [(first args) (rest args)] - [{} args]) - [logic-op preds] (if (keyword? (first preds)) - [(first preds) (rest preds)] - [:and preds]) - preds (remove nil? preds) - pred (if (>= 1 (count preds)) - (first preds) - (into [logic-op] preds))] - [m pred logic-op])) - -(defn where [& args] - (let [[m pred] (prep-where args)] - (if (nil? pred) - m - (assoc m :where pred)))) - -(defmethod build-clause :merge-where [_ m pred] - (if (nil? pred) - m - (assoc m :where (if (not (nil? (:where m))) - [:and (:where m) pred] - pred)))) - -(defn merge-where [& args] - (let [[m pred logic-op] (prep-where args)] - (if (nil? pred) - m - (assoc m :where (if (not (nil? (:where m))) - [logic-op (:where m) pred] - pred))))) - -(defhelper join [m clauses] - (assoc m :join clauses)) - -(defhelper merge-join [m clauses] - (update-in m [:join] concat clauses)) - -(defhelper left-join [m clauses] - (assoc m :left-join clauses)) - -(defhelper merge-left-join [m clauses] - (update-in m [:left-join] concat clauses)) - -(defhelper right-join [m clauses] - (assoc m :right-join clauses)) - -(defhelper merge-right-join [m clauses] - (update-in m [:right-join] concat clauses)) - -(defhelper full-join [m clauses] - (assoc m :full-join clauses)) - -(defhelper merge-full-join [m clauses] - (update-in m [:full-join] concat clauses)) - -(defhelper cross-join [m clauses] - (assoc m :cross-join clauses)) - -(defhelper merge-cross-join [m clauses] - (update-in m [:cross-join] concat clauses)) - -(defmethod build-clause :group-by [_ m fields] - (assoc m :group-by (collify fields))) - -(defn group [& args] - (let [[m fields] (if (map? (first args)) - [(first args) (rest args)] - [{} args])] - (build-clause :group-by m fields))) - -(defhelper merge-group-by [m fields] - (update-in m [:group-by] concat (collify fields))) - -(defmethod build-clause :having [_ m pred] - (if (nil? pred) - m - (assoc m :having pred))) - -(defn having [& args] - (let [[m pred] (prep-where args)] - (if (nil? pred) - m - (assoc m :having pred)))) - -(defmethod build-clause :merge-having [_ m pred] - (if (nil? pred) - m - (assoc m :having (if (not (nil? (:having m))) - [:and (:having m) pred] - pred)))) - -(defn merge-having [& args] - (let [[m pred logic-op] (prep-where args)] - (if (nil? pred) - m - (assoc m :having (if (not (nil? (:having m))) - [logic-op (:having m) pred] - pred))))) - -(defhelper order-by [m fields] - (assoc m :order-by (collify fields))) - -(defhelper merge-order-by [m fields] - (update-in m [:order-by] concat (collify fields))) - -(defhelper limit [m l] - (if (nil? l) - m - (assoc m :limit (if (coll? l) (first l) l)))) - -(defhelper offset [m o] - (if (nil? o) - m - (assoc m :offset (if (coll? o) (first o) o)))) - -(defhelper lock [m lock] - (cond-> m - lock - (assoc :lock lock))) - -(defhelper modifiers [m ms] - (if (nil? ms) - m - (assoc m :modifiers (collify ms)))) - -(defhelper merge-modifiers [m ms] - (if (nil? ms) - m - (update-in m [:modifiers] concat (collify ms)))) - -(defmethod build-clause :insert-into [_ m table] - (assoc m :insert-into table)) - -(defn insert-into - ([table] (insert-into nil table)) - ([m table] (build-clause :insert-into m table))) - -(defn- check-varargs - "Called for helpers that require unrolled arguments to catch the mistake - of passing a collection as a single argument." - [helper args] - (when (and (coll? args) (= 1 (count args)) (coll? (first args))) - (let [msg (str (name helper) " takes varargs, not a single collection")] - (throw #?(:clj (IllegalArgumentException. msg) - :cljs (js/Error. msg)))))) - -(defmethod build-clause :columns [_ m fields] - (assoc m :columns (collify fields))) - -(defn columns [& args] - (let [[m fields] (if (map? (first args)) - [(first args) (rest args)] - [{} args])] - (check-varargs :columns fields) - (build-clause :columns m fields))) - -(defmethod build-clause :merge-columns [_ m fields] - (update-in m [:columns] concat (collify fields))) - -(defn merge-columns [& args] - (let [[m fields] (if (map? (first args)) - [(first args) (rest args)] - [{} args])] - (check-varargs :merge-columns fields) - (build-clause :merge-columns m fields))) - -(defhelper composite [m vs] - (if (nil? vs) - m - (assoc m :composite (collify vs)))) - -(defmethod build-clause :values [_ m vs] - (assoc m :values vs)) - -(defn values - ([vs] (values nil vs)) - ([m vs] (build-clause :values m vs))) - -(defmethod build-clause :merge-values [_ m vs] - (update-in m [:values] concat vs)) - -(defn merge-values - ([vs] (merge-values nil vs)) - ([m vs] (build-clause :merge-values m vs))) - -(defmethod build-clause :query-values [_ m vs] - (assoc m :query-values vs)) - -(defn query-values - ([vs] (values nil vs)) - ([m vs] (build-clause :query-values m vs))) - -(defmethod build-clause :update [_ m table] - (assoc m :update table)) - -(defn update - ([table] (update nil table)) - ([m table] (build-clause :update m table))) - -(defmethod build-clause :set [_ m values] - (assoc m :set values)) - -;; short for sql set, to avoid name collision with clojure.core/set -(defn sset - ([vs] (sset nil vs)) - ([m vs] (build-clause :set m vs))) - -(defmethod build-clause :set0 [_ m values] - (assoc m :set0 values)) - -;; set with lower priority (before from) -(defn set0 - ([vs] (set0 nil vs)) - ([m vs] (build-clause :set0 m vs))) - -(defmethod build-clause :set [_ m values] - (assoc m :set values)) - -;; set with higher priority (after join) -(defn set1 - ([vs] (set1 nil vs)) - ([m vs] (build-clause :set1 m vs))) - -(defmethod build-clause :delete-from [_ m table] - (assoc m :delete-from table)) - -(defn delete-from - ([table] (delete-from nil table)) - ([m table] (build-clause :delete-from m table))) - -(defmethod build-clause :delete [_ m tables] - (assoc m :delete tables)) - -(defn delete - ([tables] (delete nil tables)) - ([m tables] (build-clause :delete m tables))) - -(defmethod build-clause :truncate [_ m table] - (assoc m :truncate table)) - -(defn truncate - ([table] (truncate nil table)) - ([m table] (build-clause :truncate m table))) - -(defhelper with [m ctes] - (assoc m :with ctes)) - -(defhelper with-recursive [m ctes] - (assoc m :with-recursive ctes)) - -(defmethod build-clause :union [_ m maps] - (assoc m :union maps)) - -(defmethod build-clause :union-all [_ m maps] - (assoc m :union-all maps)) - -(defmethod build-clause :intersect [_ m maps] - (assoc m :intersect maps)) - -(defmethod build-clause :except [_ m maps] - (assoc m :except maps)) diff --git a/test/honeysql/types.cljc b/test/honeysql/types.cljc deleted file mode 100644 index 7d9fb9d..0000000 --- a/test/honeysql/types.cljc +++ /dev/null @@ -1,105 +0,0 @@ -(ns honeysql.types - (:refer-clojure :exclude [array])) - -(defrecord SqlCall [name args]) - -(defn call - "Represents a SQL function call. Name should be a keyword." - [name & args] - (SqlCall. name args)) - -(defn read-sql-call [form] - ;; late bind so that we get new class on REPL reset - (apply #?(:clj (resolve `call) :cljs call) form)) - -;;;; - -(defrecord SqlRaw [s]) - -(defn raw - "Represents a raw SQL string" - [s] - (SqlRaw. (if (vector? s) s (str s)))) - -(defn read-sql-raw [form] - ;; late bind, as above - (#?(:clj (resolve `raw) :cljs raw) form)) - -;;;; - -(defrecord SqlParam [name]) - -(defn param - "Represents a SQL parameter which can be filled in later" - [name] - (SqlParam. name)) - -(defn param-name [^SqlParam param] - (.-name param)) - -(defn read-sql-param [form] - ;; late bind, as above - (#?(:clj (resolve `param) :cljs param) form)) - -;;;; - -(defrecord SqlArray [values]) - -(defn array - "Represents a SQL array." - [values] - (SqlArray. values)) - -(defn array-vals [^SqlArray a] - (.-values a)) - -(defn read-sql-array [form] - ;; late bind, as above - (#?(:clj (resolve `array) :cljs array) form)) - -;;;; - -(defrecord SqlInline [value]) - -(defprotocol Inlinable - (inline-str [x])) - -(defn inline - "Prevents parameterization" - [value] - (SqlInline. value)) - -(defn read-sql-inline [form] - (#?(:clj (resolve `inline) :cljs inline) form)) - -#?(:clj - (do - (defmethod print-method SqlCall [^SqlCall o ^java.io.Writer w] - (.write w (str "#sql/call " (pr-str (into [(.-name o)] (.-args o)))))) - - (defmethod print-dup SqlCall [o w] - (print-method o w)) - - (defmethod print-method SqlRaw [^SqlRaw o ^java.io.Writer w] - (.write w (str "#sql/raw " (pr-str (.s o))))) - - (defmethod print-dup SqlRaw [o w] - (print-method o w)) - - (defmethod print-method SqlParam [^SqlParam o ^java.io.Writer w] - (.write w (str "#sql/param " (pr-str (.name o))))) - - (defmethod print-dup SqlParam [o w] - (print-method o w)) - - (defmethod print-method SqlArray [^SqlArray a ^java.io.Writer w] - (.write w (str "#sql/array " (pr-str (.values a))))) - - (defmethod print-dup SqlArray [a w] - (print-method a w)) - - (defmethod print-method SqlInline [^SqlInline a ^java.io.Writer w] - (.write w (str "#sql/inline " (pr-str (.value a))))) - - (defmethod print-dup SqlInline [a w] - (print-method a w)))) diff --git a/test/honeysql/util.clj b/test/honeysql/util.clj deleted file mode 100644 index d2393aa..0000000 --- a/test/honeysql/util.clj +++ /dev/null @@ -1,5 +0,0 @@ -(ns honeysql.util) - -(defmacro defalias [sym var-sym] - `(let [v# (var ~var-sym)] - (intern *ns* (with-meta (quote ~sym) (meta v#)) @v#))) \ No newline at end of file From e6a5bdb0010cbd7251c222b5b88c861bca166991 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 04:18:14 -0700 Subject: [PATCH 232/254] Fixes #308 by adding support for clauses This also corrects the docstring for the join-by helper. --- CHANGELOG.md | 1 + doc/clause-reference.md | 25 +++++++++++++++++++++---- src/honey/sql.cljc | 12 +++++++++--- src/honey/sql/helpers.cljc | 4 ++-- test/honey/sql/helpers_test.cljc | 15 +++++++++++++++ 5 files changed, 48 insertions(+), 9 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index eb00f3f..634c860 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -4,6 +4,7 @@ * The documentation continues to be expanded and clarified in response to feedback! * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). + * Fix #308 by supporting join clauses in `join-by`. * 2.0.0-beta1 (for testing; 2021-04-09) * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 0e91e49..631c2cf 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -528,9 +528,9 @@ for more detail). ## join-by This is a convenience that allows for an arbitrary sequence of `JOIN` -operations to be performed in a specific order. It accepts a sequence -of join operation name (keyword or symbol) and the clause that join -would take: +operations to be performed in a specific order. It accepts either a sequence +of alternating join operation name (keyword or symbol) and the clause that join +would take, or a sequence of `JOIN` clauses as hash maps: ```clojure user=> (sql/format {:select [:t.ref :pp.code] @@ -540,7 +540,24 @@ user=> (sql/format {:select [:t.ref :pp.code] :join [[:logtransaction :log] [:= :t.id :log.id]]] :where [:= "settled" :pp.status]}) -["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) INNER JOIN logtransaction AS log ON t.id = log.id WHERE ? = pp.status" "settled"] +;; newlines inserted for readability: +["SELECT t.ref, pp.code FROM transaction AS t + LEFT JOIN paypal_tx AS pp USING (id) + INNER JOIN logtransaction AS log ON t.id = log.id + WHERE ? = pp.status" "settled"] +;; or using helpers: +user=> (sql/format (-> (select :t.ref :pp.code) + (from [:transaction :t]) + (join-by (left-join [:paypal-tx :pp] + [:using :id]) + (join [:logtransaction :log] + [:= :t.id :log.id])) + (where := "settled" :pp.status))) +;; newlines inserted for readability: +["SELECT t.ref, pp.code FROM transaction AS t + LEFT JOIN paypal_tx AS pp USING (id) + INNER JOIN logtransaction AS log ON t.id = log.id + WHERE ? = pp.status" "settled"] ``` Without `:join-by`, a `:join` would normally be generated before a `:left-join`. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 26fa5ac..148db70 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -464,10 +464,16 @@ (defn- format-join-by "Clauses should be a sequence of join types followed - by their table and condition, so that you can construct - a series of joins in a specific order." + by their table and condition, or a sequence of join + clauses, so that you can construct a series of joins + in a specific order." [_ clauses] - (let [joins (partition-by ident? clauses)] + (let [joins (if (every? map? clauses) + (into [] + (comp (mapcat #(mapcat (juxt key val) %)) + (map vector)) + clauses) + (partition-by ident? clauses))] (when-not (even? (count joins)) (throw (ex-info ":join-by expects a sequence of join clauses" {:clauses clauses}))) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index ae56ab2..230d6b9 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -470,8 +470,8 @@ (-> (select :*) (from :foo) - (join-by :left :bar [:= :foo.id :bar.id] - :join :quux [:= :bar.qid = :quux.id]) + (join-by :left [:bar [:= :foo.id :bar.id]] + :join [:quux [:= :bar.qid :quux.id]])) This produces a LEFT JOIN followed by an INNER JOIN even though the 'natural' order for `left-join` and diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index c71696e..c92591e 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -232,6 +232,21 @@ :right-join [:bock [:= :bock.z :c.e]] :left-join [[:clod :c] [:= :f.a :c.d]] :inner-join [:draq [:= :f.b :draq.x]]) + (sql/format))))) + (testing "Specific JOIN orders with join clauses" + (is (= ["SELECT * FROM foo FULL JOIN beck ON beck.x = c.y RIGHT JOIN bock ON bock.z = c.e LEFT JOIN clod AS c ON f.a = c.d INNER JOIN draq ON f.b = draq.x"] + (sql/format {:select [:*] :from [:foo] + :join-by [{:full-join [:beck [:= :beck.x :c.y]]} + {:right-join [:bock [:= :bock.z :c.e]]} + {:left-join [[:clod :c] [:= :f.a :c.d]]} + {:join [:draq [:= :f.b :draq.x]]}]}))) + (is (= ["SELECT * FROM foo FULL JOIN beck ON beck.x = c.y RIGHT JOIN bock ON bock.z = c.e LEFT JOIN clod AS c ON f.a = c.d INNER JOIN draq ON f.b = draq.x"] + (-> (select :*) + (from :foo) + (join-by (full-join :beck [:= :beck.x :c.y]) + (right-join :bock [:= :bock.z :c.e]) + (left-join [:clod :c] [:= :f.a :c.d]) + (join :draq [:= :f.b :draq.x])) (sql/format)))))) (deftest test-cast From 684b33a03a7498306c798bfb6894867d6c80f1f5 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 11 Apr 2021 04:39:35 -0700 Subject: [PATCH 233/254] Note correction to join-by docstring --- CHANGELOG.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 634c860..38b3350 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -4,7 +4,7 @@ * The documentation continues to be expanded and clarified in response to feedback! * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). - * Fix #308 by supporting join clauses in `join-by`. + * Fix #308 by supporting join clauses in `join-by` (and correcting the helper docstring). * 2.0.0-beta1 (for testing; 2021-04-09) * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). From 272b0889182c35b6aaf7dd0f65c3187296e7bf32 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 12 Apr 2021 15:04:17 -0700 Subject: [PATCH 234/254] Revert "Addresses #315 by expanding IN to handle nil" This reverts commit 8a1e2cca712c52dadbeb26834287968eb650b7e1. --- CHANGELOG.md | 1 - src/honey/sql.cljc | 33 ++++++------------------ test/honey/sql/helpers_test.cljc | 43 -------------------------------- 3 files changed, 8 insertions(+), 69 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 38b3350..5d55dd3 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -2,7 +2,6 @@ * 2.0.next in progress * The documentation continues to be expanded and clarified in response to feedback! - * Tentative fix for #315 by expanding `:in` handling to deal with `nil` values. * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). * Fix #308 by supporting join clauses in `join-by` (and correcting the helper docstring). diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 148db70..337d02c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -927,34 +927,17 @@ x)) (defn- format-in [in [x y]] - (let [nil-check (and (sequential? y) (not (ident? (first y)))) - y' (if nil-check (remove nil? y) y) - [sql-x & params-x] (format-expr x {:nested true}) - [sql-y & params-y] (format-expr y' {:nested true}) + (let [[sql-x & params-x] (format-expr x {:nested true}) + [sql-y & params-y] (format-expr y {:nested true}) values (unwrap (first params-y) {})] (if (and (= "?" sql-y) (= 1 (count params-y)) (coll? values)) - (let [values' (remove nil? values) - sql (str "(" (str/join ", " (repeat (count values') "?")) ")") - in (str sql-x " " (sql-kw in) " " sql)] - (-> [(if (not= (count values) (count values')) - (if (zero? (count values')) - (str sql-x " IS NULL") - (str "(" in " OR " sql-x " IS NULL)")) - (if (zero? (count values)) - "FALSE" - in))] + (let [sql (str "(" (str/join ", " (repeat (count values) "?")) ")")] + (-> [(str sql-x " " (sql-kw in) " " sql)] (into params-x) - (into values'))) - (let [in (str sql-x " " (sql-kw in) " " sql-y)] - (-> [(if (and nil-check (not= (count y) (count y'))) - (if (zero? (count y')) - (str sql-x " IS NULL") - (str "(" in " OR " sql-x " IS NULL)")) - (if (zero? (count y)) - "FALSE" - in))] - (into params-x) - (into params-y)))))) + (into values))) + (-> [(str sql-x " " (sql-kw in) " " sql-y)] + (into params-x) + (into params-y))))) (defn- function-0 [k xs] [(str (sql-kw k) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index c92591e..14d1ce3 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -290,39 +290,6 @@ :from [:customers] :where [:in :id values]}))) (is (= ["SELECT * FROM customers WHERE id IN (?)" 1] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:params {:ids values}}))))) - (testing (str "with just a nil value from a " (name cname)) - (let [values (conj coll nil)] - (is (= ["SELECT * FROM customers WHERE id IS NULL"] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE id IS NULL"] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:params {:ids values}}))))) - (testing (str "with nil values from a " (name cname)) - (let [values (conj coll 1 nil)] - (is (= ["SELECT * FROM customers WHERE (id IN (?) OR id IS NULL)" 1] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE (id IN (?) OR id IS NULL)" 1] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:params {:ids values}}))))) - (testing (str "with no values from a " (name cname)) - (let [values coll] - (is (= ["SELECT * FROM customers WHERE FALSE"] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE FALSE"] (sql/format {:select [:*] :from [:customers] :where [:in :id :?ids]} @@ -334,16 +301,6 @@ :from [:customers] :where [:in :id values]}))) (is (= ["SELECT * FROM customers WHERE id IN (?, ?)" 1 2] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id :?ids]} - {:params {:ids values}})))) - (let [values [1 nil 2]] - (is (= ["SELECT * FROM customers WHERE (id IN (?, ?) OR id IS NULL)" 1 2] - (sql/format {:select [:*] - :from [:customers] - :where [:in :id values]}))) - (is (= ["SELECT * FROM customers WHERE (id IN (?, ?) OR id IS NULL)" 1 2] (sql/format {:select [:*] :from [:customers] :where [:in :id :?ids]} From dd52ebe7e8949a3ee0f4cb07de0da16d9c05243d Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 13 Apr 2021 12:51:21 -0700 Subject: [PATCH 235/254] Fixes #322 by rewriting where/having merge --- CHANGELOG.md | 1 + src/honey/sql/helpers.cljc | 94 ++++++++++++++++++-------------- test/honey/sql/helpers_test.cljc | 14 +++++ 3 files changed, 69 insertions(+), 40 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 5d55dd3..aa29811 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -2,6 +2,7 @@ * 2.0.next in progress * The documentation continues to be expanded and clarified in response to feedback! + * Fix #322 by rewriting/simplifying `WHERE`/`HAVING` merge logic. * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). * Fix #308 by supporting join clauses in `join-by` (and correcting the helper docstring). diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 230d6b9..27f2ca7 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -11,53 +11,67 @@ (defn- default-merge [current args] (c/into (vec current) args)) -(defn- and-merge - "Merge a single conjunction expression into an existing one. - This merges `AND` to avoid nesting." - [current arg] - (if-let [conj' (and (sequential? arg) - (ident? (first arg)) - (#{:and :or} (keyword (first arg))))] - (cond (= conj' (first current)) - (c/into (vec current) (rest arg)) - (seq current) - (c/into [conj' current] (rest arg)) - :else - (c/into [conj'] (rest arg))) - (cond (#{:and 'and} (first current)) - (conj (vec current) arg) - (seq current) - (conj [:and current] arg) - :else - (conj [:and] arg)))) +(defn- sym->kw + "Given a symbol, produce a keyword, retaining the namespace + qualifier, if any." + [s] + (if (symbol? s) + (if-let [n (namespace s)] + (keyword n (name s)) + (keyword (name s))) + s)) -(defn- and-merges - "Merge multiple conjunction expressions into an existing, - possibly empty, expression. This ensures AND expressions - are merged and that we do not end up with a single AND - or OR expression." +(defn- conjunction? + [e] + (and (ident? e) + (contains? #{:and :or} (sym->kw e)))) + +(defn- simplify-logic + "For Boolean expressions, simplify the logic to make + the output expression less nested. Finding :and or + :or with a single condition can be lifted. Finding + a conjunction inside the same conjunction can be + merged. + Always called on an expression that begins with a conjunction!" + [e] + (if (= 1 (count (rest e))) + (fnext e) + (let [conjunction (sym->kw (first e))] + (reduce (fn [acc e] + (if (and (sequential? e) + (conjunction? (first e)) + (= conjunction (sym->kw (first e)))) + (c/into acc (rest e)) + (conj acc e))) + [conjunction] + (rest e))))) + +(defn- conjunction-merge + "Merge for where/having. We ignore nil expressions. + By default, we combine with AND unless the new expression + begins with a conjunction, in which case use that to + combine the new expression. Then we perform some + simplifications to reduce nesting." [current args] (let [args (remove nil? args) - result - (cond (ident? (first args)) - (and-merges current [args]) - (seq args) - (let [[arg & args] args] - (and-merges (and-merge current arg) args)) + [conjunction args] + (cond (conjunction? (first args)) + [(first args) (rest args)] + (ident? (first args)) + [:and [args]] :else - current)] - (case (count result) - 0 nil - 1 (if (sequential? (first result))(first result) result) - 2 (if (#{:and :or} (first result)) - (second result) - result) - result))) + [:and args])] + (if (seq args) + (-> [conjunction] + (cond-> (seq current) (conj current)) + (c/into args) + (simplify-logic)) + current))) (def ^:private special-merges "Identify the conjunction merge clauses." - {:where #'and-merges - :having #'and-merges}) + {:where #'conjunction-merge + :having #'conjunction-merge}) (defn- helper-merge [data k args] (if-let [merge-fn (special-merges k)] diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 14d1ce3..355bf71 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -843,3 +843,17 @@ " SUM(q) FILTER (WHERE x IS NULL) AS b," " FOO(y) WITHIN GROUP (ORDER BY x ASC)") 5 10])))) + +(deftest issue-322 + (testing "Combining WHERE clauses with conditions" + (is (= {:where [:and [:= :a 1] [:or [:= :b 2] [:= :c 3]]]} + (where [:= :a 1] [:or [:= :b 2] [:= :c 3]]))) + (is (= (-> (where :or [:= :b 2] [:= :c 3]) ; or first + (where := :a 1)) ; then implicit and + (-> (where := :b 2) ; implicit and + (where :or [:= :c 3]) ; then explicit or + (where := :a 1)))) ; then implicit and + (is (= {:where [:and [:or [:= :b 2] [:= :c 3]] [:= :a 1]]} + (where [:or [:= :b 2] [:= :c 3]] [:= :a 1]) + (-> (where :or [:= :b 2] [:= :c 3]) ; explicit or + (where := :a 1)))))) ; then implicit and From e227e1b9ab89417f2dbb8634104eea67feb4d1fc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 13 Apr 2021 12:55:40 -0700 Subject: [PATCH 236/254] Prep for 2.0.0-beta2 --- CHANGELOG.md | 5 +++-- README.md | 2 +- doc/differences-from-1-x.md | 2 +- doc/general-reference.md | 2 +- doc/getting-started.md | 6 +++--- doc/postgresql.md | 2 +- pom.xml | 4 ++-- 7 files changed, 12 insertions(+), 11 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index aa29811..9afe36d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,12 +1,13 @@ # Changes -* 2.0.next in progress +* 2.0.0-beta2 (for testing; 2021-04-13) * The documentation continues to be expanded and clarified in response to feedback! - * Fix #322 by rewriting/simplifying `WHERE`/`HAVING` merge logic. + * Fix #322 by rewriting/simplifying `WHERE`/`HAVING` merge logic. **Important bug fix!** * Fix #310 by adding support for `FILTER`, `WITHIN GROUP`, and `ORDER BY` (as an expression), from [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) 0.4.112. These are [Special Syntax](doc/special-syntax.md) and there are also helpers for `filter` and `within-group` -- so **be careful about referring in all of `honey.sql.helpers`** since it will now shadow `clojure.core/filter` (it already shadows `for`, `group-by`, `into`, `partition-by`, `set`, and `update`). * Fix #308 by supporting join clauses in `join-by` (and correcting the helper docstring). * 2.0.0-beta1 (for testing; 2021-04-09) + * **The merging behavior of `where`/`having` is broken in Beta 1!** * Since Alpha 3, more documentation has been written and existing documentation clarified (addressing #300, #309, #313, #314). * Fix #319 by ensuring `register-clause!` is idempotent. * Fix #317 by dropping qualifiers in `:set` clauses (just like we do with `:insert` columns). Note that you can still use explicit _dotted_ names if you want table qualification. diff --git a/README.md b/README.md index bb4b356..a863227 100644 --- a/README.md +++ b/README.md @@ -4,7 +4,7 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta2)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2) This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 3cc0b45..8217ec6 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -49,7 +49,7 @@ Supported Clojure versions: 1.7 and later. ```clojure ;; in deps.edn: -com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta1"} +com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta2"} ;; in use: (ns my.project diff --git a/doc/general-reference.md b/doc/general-reference.md index 856f9ad..660d3ca 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -114,6 +114,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.x, this [overview of differences between 1.x and 2.x](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index 3f6f39f..d5ea8dc 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta1"} + com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta2"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [com.github.seancorfield/honeysql "2.0.0-beta1"] + [com.github.seancorfield/honeysql "2.0.0-beta2"] ``` HoneySQL produces SQL statements but does not execute them. @@ -327,7 +327,7 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta1/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2/api/honey.sql.helpers) namespace. More detail about certain core HoneySQL functionality can be found in the [Reference documentation](general-reference.md). If you're migrating to HoneySQL 2.x, this [overview of differences diff --git a/doc/postgresql.md b/doc/postgresql.md index ec48ae6..567c798 100644 --- a/doc/postgresql.md +++ b/doc/postgresql.md @@ -341,7 +341,7 @@ user=> (sql/format (alter-table :fruit `honeysql-postgres` added support for `FILTER` and `WITHIN GROUP` in its 0.4.112 release. Those features have been integrated into -HoneySQL 2.x (as of 2.0.next), along with support for `ORDER BY` +HoneySQL 2.x (as of 2.0.0-beta2), along with support for `ORDER BY` in expressions. `:filter`, `:within-group`, and `:order-by` are all available as "functions" in [Special Syntax](special-syntax.md), and there are helpers for `filter` and `within-group`. diff --git a/pom.xml b/pom.xml index f68b9d8..50ffdaa 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 com.github.seancorfield honeysql - 2.0.0-beta1 + 2.0.0-beta2 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-beta1 + v2.0.0-beta2 From f606dc6044bd7fa112f12c935d6fa0e854eb4484 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 22 Apr 2021 19:16:30 -0700 Subject: [PATCH 237/254] Fixes #323 by allowing multiple column names --- CHANGELOG.md | 3 +++ doc/clause-reference.md | 9 +++---- src/honey/sql.cljc | 39 +++++++++++++++---------------- src/honey/sql/helpers.cljc | 7 +++--- test/honey/sql/postgres_test.cljc | 14 +++++++++++ test/honey/sql_test.cljc | 26 +++++++++++++++++++++ 6 files changed, 70 insertions(+), 28 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 9afe36d..4dd79b7 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.next in progress + * Fix #323 by supporting more than one SQL entity in `:on-conflict`. + * 2.0.0-beta2 (for testing; 2021-04-13) * The documentation continues to be expanded and clarified in response to feedback! * Fix #322 by rewriting/simplifying `WHERE`/`HAVING` merge logic. **Important bug fix!** diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 631c2cf..df93457 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -815,10 +815,11 @@ These are grouped together because they are handled as if they are separate clauses but they will appear in pairs: `ON ... DO ...`. -`:on-conflict` accepts either a single SQL entity -(a keyword or symbol), or a SQL clause, or a pair -of a SQL entity and a SQL clause. The SQL entity is -a column name and the SQL clause can be an +`:on-conflict` accepts a sequence of zero or more +SQL entities (keywords or symbols), optionally +followed by a single SQL clause (hash map). It can also +accept either a single SQL entity or a single SQL clause. +The SQL entities are column names and the SQL clause can be an `:on-constraint` clause or a`:where` clause. _[For convenience of use with the `on-conflict` helper, this clause can also accept any of those arguments, wrapped in a sequence; it can also accept an empty sequence, and just produce `ON CONFLICT`, so that it can be combined with other clauses directly]_ diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 337d02c..1c70232 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -589,26 +589,25 @@ (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-on-conflict [k x] - (cond (ident? x) - [(str (sql-kw k) " (" (format-entity x) ")")] - (map? x) - (let [[sql & params] (format-dsl x)] - (into [(str (sql-kw k) " " sql)] params)) - (and (sequential? x) - (ident? (first x)) - (map? (second x))) - (let [[sql & params] (format-dsl (second x))] - (into [(str (sql-kw k) - " (" (format-entity (first x)) ") " - sql)] - params)) - (and (sequential? x) (= 1 (count x))) - (format-on-conflict k (first x)) - (and (sequential? x) (= 0 (count x))) - [(sql-kw k)] - :else - (throw (ex-info "unsupported :on-conflict format" - {:clause x})))) + (if (sequential? x) + (let [entities (take-while ident? x) + n (count entities) + [clause & more] (drop n x) + _ (when (or (seq more) + (and clause (not (map? clause)))) + (throw (ex-info "unsupported :on-conflict format" + {:clause x}))) + [sql & params] (when clause + (format-dsl clause))] + (into [(str (sql-kw k) + (when (pos? n) + (str " (" + (str/join ", " (map #'format-entity entities)) + ")")) + (when sql + (str " " sql)))] + params)) + (format-on-conflict k [x]))) (defn- format-do-update-set [k x] (cond (map? x) diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 27f2ca7..95dde1a 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -768,10 +768,9 @@ (generic-1 :values args)) (defn on-conflict - "Accepts a single column name to detect conflicts - during an upsert, optionally followed by a `WHERE` - clause." - {:arglists '([column] [column where-clause])} + "Accepts zero or more SQL entities (keywords or symbols), + optionally followed by a single SQL clause (hash map)." + {:arglists '([column* where-clause])} [& args] (generic :on-conflict args)) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 86d9852..4a5685b 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -72,6 +72,20 @@ (on-conflict (on-constraint :distributors_pkey)) do-nothing sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did) ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + ;; with both name and clause: + (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + (on-conflict :did (on-constraint :distributors_pkey)) + do-nothing + sql/format))) + (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT (did, dname) ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] + ;; with multiple names and a clause: + (-> (insert-into :distributors) + (values [{:did 9 :dname "Antwerp Design"}]) + (on-conflict :did :dname (on-constraint :distributors_pkey)) + do-nothing + sql/format))) (is (= ["INSERT INTO distributors (did, dname) VALUES (?, ?) ON CONFLICT ON CONSTRAINT distributors_pkey DO NOTHING" 9 "Antwerp Design"] ;; almost identical to nilenso version: (-> (insert-into :distributors) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 4dd43dd..0a73eb9 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -618,6 +618,32 @@ INSERT INTO customers (name, email) VALUES ('Microsoft', 'hotline@microsoft.com') ON CONFLICT (name) +DO NOTHING +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict [:name] + :do-nothing true} + {:pretty true}))) + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT (name, email) +DO NOTHING +"] + (format {:insert-into :customers + :columns [:name :email] + :values [[[:inline "Microsoft"], [:inline "hotline@microsoft.com"]]] + :on-conflict [:name :email] + :do-nothing true} + {:pretty true}))) + (is (= [" +INSERT INTO customers +(name, email) +VALUES ('Microsoft', 'hotline@microsoft.com') +ON CONFLICT (name) DO UPDATE SET email = EXCLUDED.email || ';' || customers.email "] (format {:insert-into :customers From 20cba15da22946d60f53dd6913caba990f7cddb7 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 22 Apr 2021 22:13:32 -0700 Subject: [PATCH 238/254] Fixes #321 by adding :checking option Initial linting is only for IN () and IN (NULL) --- CHANGELOG.md | 1 + doc/getting-started.md | 10 +++++++++- src/honey/sql.cljc | 15 +++++++++++++++ test/honey/sql_test.cljc | 41 +++++++++++++++++++++++++++++++++++++--- 4 files changed, 63 insertions(+), 4 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 4dd79b7..d896711 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -2,6 +2,7 @@ * 2.0.next in progress * Fix #323 by supporting more than one SQL entity in `:on-conflict`. + * Fix #321 by adding `:checking` mode. Currently only detects potential problems with `IN` clauses. * 2.0.0-beta2 (for testing; 2021-04-13) * The documentation continues to be expanded and clarified in response to feedback! diff --git a/doc/getting-started.md b/doc/getting-started.md index d5ea8dc..019373f 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -297,7 +297,7 @@ HoneySQL supports quite a few [PostgreSQL extensions](postgresql.md). ## Format Options In addition to the `:quoted` and `:dialect` options described above, -`format` also accepts `:inline` and `:params`. +`format` also accepts `:checking`, `:inline`, and `:params`. The `:params` option was mentioned above and is used to specify the values of named parameters in the DSL. @@ -312,6 +312,14 @@ was wrapped in `[:inline `..`]`: * keywords and symbols become SQL keywords (uppercase, with `-` replaced by a space), * everything else is just turned into a string (by calling `str`) and added to the SQL string. +The `:checking` option defaults to `:none`. If `:checking :basic` is +specified, certain obvious errors -- such as `IN` with an empty collection -- +is treated as an error and an exception is thrown. If `:checking :strict` +is specified, certain dubious constructs -- such as `IN` with a collection +containing `NULL` values -- is also treated as an error and an exception is +thrown. It is expected that this feature will be expanded over time +to help avoid generating illegal SQL. _[New in version 2.0.next]_ + `format` accepts options as either a single hash map argument or as named arguments (alternating keys and values). If you are using Clojure 1.11 (or later) you can mix'n'match, providing some options diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 1c70232..e46f85c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -106,6 +106,8 @@ ;; in entities; if someone complains about this check, an option ;; can be added to format to turn this on: (def ^:private ^:dynamic *allow-suspicious-entities* false) +;; "linting" mode (:none, :basic, :strict): +(def ^:private ^:dynamic *checking* :none) ;; clause helpers @@ -929,6 +931,16 @@ (let [[sql-x & params-x] (format-expr x {:nested true}) [sql-y & params-y] (format-expr y {:nested true}) values (unwrap (first params-y) {})] + (when-not (= :none *checking*) + (when (or (and (sequential? y) (empty? y)) + (and (sequential? values) (empty? values))) + (throw (ex-info "IN () empty collection is illegal" + {:clause [in x y]}))) + (when (and (= :strict *checking*) + (or (and (sequential? y) (some nil? y)) + (and (sequential? values) (some nil? values)))) + (throw (ex-info "IN (NULL) does not match" + {:clause [in x y]})))) (if (and (= "?" sql-y) (= 1 (count params-y)) (coll? values)) (let [sql (str "(" (str/join ", " (repeat (count values) "?")) ")")] (-> [(str sql-x " " (sql-kw in) " " sql)] @@ -1228,6 +1240,9 @@ (let [dialect? (contains? opts :dialect) dialect (when dialect? (get dialects (check-dialect (:dialect opts))))] (binding [*dialect* (if dialect? dialect @default-dialect) + *checking* (if (contains? opts :checking) + (:checking opts) + :none) *clause-order* (if dialect? (if-let [f (:clause-order-fn dialect)] (f @base-clause-order) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 0a73eb9..489807b 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -6,7 +6,8 @@ #?(:clj [clojure.test :refer [deftest is testing]] :cljs [cljs.test :refer-macros [deftest is testing]]) [honey.sql :as sut :refer [format]] - [honey.sql.helpers :as h])) + [honey.sql.helpers :as h]) + #?(:clj (:import (clojure.lang ExceptionInfo)))) (deftest mysql-tests (is (= ["SELECT * FROM `table` WHERE `id` = ?" 1] @@ -685,9 +686,9 @@ ORDER BY id = ? DESC (format)) (is false "; not detected in entity!") (catch #?(:clj Throwable :cljs :default) e - (is (:disallowed (ex-data e)))))) + (is (:disallowed (ex-data e)))))))) ;; should not produce: ["SELECT foo, bar FROM mytable ORDER BY foo; select * from users"] - )) + (deftest issue-319-test (testing "that registering a clause is idempotent" @@ -696,3 +697,37 @@ ORDER BY id = ? DESC (sut/register-clause! :foo (constantly ["FOO"]) nil) (sut/register-clause! :foo (constantly ["FOO"]) nil) (format {:foo []})))))) + +(deftest issue-321-linting + (testing "empty IN is ignored by default" + (is (= ["WHERE x IN ()"] + (format {:where [:in :x []]}))) + (is (= ["WHERE x IN ()"] + (format {:where [:in :x :?y]} + {:params {:y []}})))) + (testing "empty IN is flagged in basic mode" + (is (thrown-with-msg? ExceptionInfo #"empty collection" + (format {:where [:in :x []]} + {:checking :basic}))) + (is (thrown-with-msg? ExceptionInfo #"empty collection" + (format {:where [:in :x :?y]} + {:params {:y []} :checking :basic})))) + (testing "IN NULL is ignored by default and basic" + (is (= ["WHERE x IN (NULL)"] + (format {:where [:in :x [nil]]}))) + (is (= ["WHERE x IN (NULL)"] + (format {:where [:in :x [nil]]} + {:checking :basic}))) + (is (= ["WHERE x IN (?)" nil] + (format {:where [:in :x :?y]} + {:params {:y [nil]}}))) + (is (= ["WHERE x IN (?)" nil] + (format {:where [:in :x :?y]} + {:params {:y [nil]} :checking :basic})))) + (testing "IN NULL is flagged in strict mode" + (is (thrown-with-msg? ExceptionInfo #"does not match" + (format {:where [:in :x [nil]]} + {:checking :strict}))) + (is (thrown-with-msg? ExceptionInfo #"does not match" + (format {:where [:in :x :?y]} + {:params {:y [nil]} :checking :strict}))))) From 46b3c1773b57ad17efda63f5ceee4f24c221ad0a Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 1 May 2021 12:56:42 -0700 Subject: [PATCH 239/254] Fixes #324 by correcting insert-into --- CHANGELOG.md | 1 + src/honey/sql/helpers.cljc | 8 +++++--- test/honey/sql/helpers_test.cljc | 9 +++++++++ 3 files changed, 15 insertions(+), 3 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index d896711..d73c680 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,7 @@ # Changes * 2.0.next in progress + * Fix #324 so that `insert-into` supports merging into another statement in all cases. * Fix #323 by supporting more than one SQL entity in `:on-conflict`. * Fix #321 by adding `:checking` mode. Currently only detects potential problems with `IN` clauses. diff --git a/src/honey/sql/helpers.cljc b/src/honey/sql/helpers.cljc index 95dde1a..8c9f40d 100644 --- a/src/honey/sql/helpers.cljc +++ b/src/honey/sql/helpers.cljc @@ -398,10 +398,12 @@ (-> (select :*) (from :other)))" {:arglists '([table] [table cols] [table statement] [table cols statement])} [& args] - (let [[table cols statement] args] + (let [[data & args :as args'] + (if (map? (first args)) args (cons {} args)) + [table cols statement] args] (if (and (sequential? cols) (map? statement)) - (generic :insert-into [[table cols] statement]) - (generic :insert-into args)))) + (generic :insert-into [data [table cols] statement]) + (generic :insert-into args')))) (defn update "Accepts either a table name or a table/alias pair. diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 355bf71..33ea68c 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -857,3 +857,12 @@ (where [:or [:= :b 2] [:= :c 3]] [:= :a 1]) (-> (where :or [:= :b 2] [:= :c 3]) ; explicit or (where := :a 1)))))) ; then implicit and + +(deftest issue-324 + (testing "insert-into accepts statement" + (is (= (-> (with [:a]) + (insert-into [:quux [:x :y]] + {:select [:id] :from [:table]})) + {:with [[:a]], + :insert-into [[:quux [:x :y]] + {:select [:id], :from [:table]}]})))) From 11fcfd525741143203303e45ebb5653038dd3122 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Thu, 6 May 2021 22:12:46 -0700 Subject: [PATCH 240/254] Prep for 2.0.0-rc1 --- CHANGELOG.md | 2 +- README.md | 4 ++-- doc/differences-from-1-x.md | 2 +- doc/general-reference.md | 2 +- doc/getting-started.md | 12 ++++++------ pom.xml | 4 ++-- 6 files changed, 13 insertions(+), 13 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index d73c680..63f1ef6 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,6 @@ # Changes -* 2.0.next in progress +* 2.0.0-rc1 (for testing; 2021-05-06) * Fix #324 so that `insert-into` supports merging into another statement in all cases. * Fix #323 by supporting more than one SQL entity in `:on-conflict`. * Fix #321 by adding `:checking` mode. Currently only detects potential problems with `IN` clauses. diff --git a/README.md b/README.md index a863227..1f26a21 100644 --- a/README.md +++ b/README.md @@ -4,9 +4,9 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-beta2)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-rc1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1) -This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. +Once the prerelease testing is complete, this project will follow the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. HoneySQL 2.x requires Clojure 1.9 or later. diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 8217ec6..c0f041b 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -49,7 +49,7 @@ Supported Clojure versions: 1.7 and later. ```clojure ;; in deps.edn: -com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta2"} +com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc1"} ;; in use: (ns my.project diff --git a/doc/general-reference.md b/doc/general-reference.md index 660d3ca..cce936a 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -114,6 +114,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.x, this [overview of differences between 1.x and 2.x](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index 019373f..e7e3615 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - com.github.seancorfield/honeysql {:mvn/version "2.0.0-beta2"} + com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc1"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [com.github.seancorfield/honeysql "2.0.0-beta2"] + [com.github.seancorfield/honeysql "2.0.0-rc1"] ``` HoneySQL produces SQL statements but does not execute them. @@ -314,11 +314,11 @@ was wrapped in `[:inline `..`]`: The `:checking` option defaults to `:none`. If `:checking :basic` is specified, certain obvious errors -- such as `IN` with an empty collection -- -is treated as an error and an exception is thrown. If `:checking :strict` +are treated as an error and an exception is thrown. If `:checking :strict` is specified, certain dubious constructs -- such as `IN` with a collection -containing `NULL` values -- is also treated as an error and an exception is +containing `NULL` values -- are also treated as an error and an exception is thrown. It is expected that this feature will be expanded over time -to help avoid generating illegal SQL. _[New in version 2.0.next]_ +to help avoid generating illegal SQL. _[New in version 2.0.0-rc1]_ `format` accepts options as either a single hash map argument or as named arguments (alternating keys and values). If you are using @@ -335,7 +335,7 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-beta2/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1/api/honey.sql.helpers) namespace. More detail about certain core HoneySQL functionality can be found in the [Reference documentation](general-reference.md). If you're migrating to HoneySQL 2.x, this [overview of differences diff --git a/pom.xml b/pom.xml index 50ffdaa..2f661a7 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 com.github.seancorfield honeysql - 2.0.0-beta2 + 2.0.0-rc1 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-beta2 + v2.0.0-rc1 From d73560b7e34decca6061de6f0739ae0e977280e6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 8 May 2021 21:01:28 -0700 Subject: [PATCH 241/254] Add :quoted-snake option --- CHANGELOG.md | 4 +++ doc/differences-from-1-x.md | 2 +- src/honey/sql.cljc | 45 ++++++++++++++++++------------- test/honey/sql/postgres_test.cljc | 30 ++++++++++----------- 4 files changed, 47 insertions(+), 34 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 63f1ef6..1a0125d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,9 @@ # Changes +* 2.0.next in progress + * Add `:quoted-snake true` option to force conversion from kebab-case to snake_case when `:quoted true` or a `:dialect` is specified to `format`. + * TBD `%` function syntax may respect `:quoted true` or a `:dialect` is specified to `format` (awaiting PR). + * 2.0.0-rc1 (for testing; 2021-05-06) * Fix #324 so that `insert-into` supports merging into another statement in all cases. * Fix #323 by supporting more than one SQL entity in `:on-conflict`. diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index c0f041b..365c159 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -85,7 +85,7 @@ The `:quoting ` option has superseded by the new dialect machinery and Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. The following options are no longer supported: -* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). +* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). If you want dashed-names to be converted to snake_case when `:quoted true`, you also need to specify `:quoted-snake true`. _[New in 2.0.next]_ * `:allow-namespaced-names?` -- this supported `foo/bar` column names in SQL which I'd like to discourage. * `:namespace-as-table?` -- this is the default in 2.x: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. * `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index e46f85c..4514180 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -100,6 +100,7 @@ ;; functions harder than necessary: (def ^:private ^:dynamic *clause-order* default-clause-order) (def ^:private ^:dynamic *quoted* nil) +(def ^:private ^:dynamic *quoted-snake* nil) (def ^:private ^:dynamic *inline* nil) (def ^:private ^:dynamic *params* nil) ;; there is no way, currently, to enable suspicious characters @@ -165,21 +166,23 @@ return the equivalent SQL fragment (as a string -- no parameters). Handles quoting, splitting at / or ., replacing - with _ etc." - [x & [{:keys [aliased drop-ns]}]] - (let [nn (if (or *quoted* (string? x)) name name-_) - q (if (or *quoted* (string? x)) (:quote *dialect*) identity) - [t c] (if-let [n (when-not (or drop-ns (string? x)) - (namespace-_ x))] - [n (nn x)] - (if aliased - [nil (nn x)] - (let [[t c] (str/split (nn x) #"\.")] - (if c [t c] [nil t])))) - entity (cond->> c - (not= "*" c) - (q) - t - (str (q t) ".")) + [e & [{:keys [aliased drop-ns]}]] + (let [col-fn (if (or *quoted* (string? e)) + (if *quoted-snake* name-_ name) + name-_) + quote-fn (if (or *quoted* (string? e)) (:quote *dialect*) identity) + [table col] (if-let [n (when-not (or drop-ns (string? e)) + (namespace-_ e))] + [n (col-fn e)] + (if aliased + [nil (col-fn e)] + (let [[t c] (str/split (col-fn e) #"\.")] + (if c [t c] [nil t])))) + entity (cond->> col + (not= "*" col) + (quote-fn) + table + (str (quote-fn table) ".")) suspicious #";"] (when-not *allow-suspicious-entities* (when (re-find suspicious entity) @@ -188,11 +191,15 @@ entity)) (comment - (for [v [:foo-bar 'foo-bar "foo-bar" - :f-o.bar 'f-o.bar "f-o.bar"] + (for [v [:foo-bar "foo-bar" ; symbol is the same as keyword + :f-o.b-r :f-o/b-r] a [true false] d [true false] q [true false]] (binding [*dialect* (:mysql dialects) *quoted* q] - (format-entity v :aliased a :drop-ns d))) + (if q + [v a d (format-entity v {:aliased a :drop-ns d}) + (binding [*quoted-snake* true] + (format-entity v {:aliased a :drop-ns d}))] + [v a d (format-entity v {:aliased a :drop-ns d})]))) .) (defn- param-value [k] @@ -1253,6 +1260,8 @@ *quoted* (if (contains? opts :quoted) (:quoted opts) dialect?) + *quoted-snake* (when (contains? opts :quoted-snake) + (:quoted-snake opts)) *params* (:params opts)] (mapv #(unwrap % opts) (format-dsl data opts))))) ([data k v & {:as opts}] (format data (assoc opts k v)))) diff --git a/test/honey/sql/postgres_test.cljc b/test/honey/sql/postgres_test.cljc index 4a5685b..ad17359 100644 --- a/test/honey/sql/postgres_test.cljc +++ b/test/honey/sql/postgres_test.cljc @@ -14,21 +14,21 @@ ;; pull in all the PostgreSQL helpers that the nilenso ;; library provided (as well as the regular HoneySQL ones): [honey.sql.helpers :as sqlh :refer - [upsert on-conflict do-nothing on-constraint - returning do-update-set - ;; not needed because do-update-set can do this directly - #_do-update-set! - alter-table rename-column drop-column - add-column partition-by - ;; not needed because insert-into can do this directly - #_insert-into-as - create-table rename-table drop-table - window create-view over with-columns - create-extension drop-extension - select-distinct-on - ;; already part of HoneySQL - insert-into values where select - from order-by update set]] + [upsert on-conflict do-nothing on-constraint + returning do-update-set + ;; not needed because do-update-set can do this directly + #_do-update-set! + alter-table rename-column drop-column + add-column partition-by + ;; not needed because insert-into can do this directly + #_insert-into-as + create-table rename-table drop-table + window create-view over with-columns + create-extension drop-extension + select-distinct-on + ;; already part of HoneySQL + insert-into values where select + from order-by update set]] [honey.sql :as sql])) (deftest upsert-test From 6ebc0179698a6d900ffe7c137120e3a94b638d08 Mon Sep 17 00:00:00 2001 From: Neil McCalum Date: Sun, 9 May 2021 17:18:39 +1200 Subject: [PATCH 242/254] quoting for :%fun.col(s) syntax to match with [[:fun :col]] --- src/honey/sql.cljc | 10 ++++++---- test/honey/sql/helpers_test.cljc | 24 ++++++++++++++++++++++++ 2 files changed, 30 insertions(+), 4 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4514180..b3b69d4 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -214,11 +214,13 @@ (fn [fk _] (param-value (fk)))})) (defn- format-var [x & [opts]] - (let [c (name-_ x)] + (let [c (name x)] (cond (= \% (first c)) - (let [[f & args] (str/split (subs c 1) #"\.")] - ;; TODO: this does not quote arguments -- does that matter? - [(str (upper-case f) "(" (str/join "," args) ")")]) + (let [[f & args] (str/split (subs c 1) #"\.") + quoted-args (->> args + (map keyword) + (map format-entity))] + [(str (upper-case f) "(" (str/join "," quoted-args) ")")]) (= \? (first c)) (let [k (keyword (subs c 1))] (if *inline* diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 33ea68c..60e9a4d 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -866,3 +866,27 @@ {:with [[:a]], :insert-into [[:quux [:x :y]] {:select [:id], :from [:table]}]})))) + +(deftest quoting-:%-syntax + (testing "quoting of expressions in functions shouldn't depend on syntax" + (is (= [(str "SELECT `foo-bar`," + " COUNT(*)," + " COUNT(*)," + " SYSDATE()," + " SYSDATE()," + " AVG(`bar-bar`)," + " AVG(`bar-bar`,`bar-foo`)," + " SUM(`foo-foo`)" + " FROM `employee`" + " GROUP BY `foo-bar`")] + (-> (select :foo-bar + [[:count :*]] + :%count.* + :%sysdate + :%sysdate. + :%avg.bar-bar + :%avg.bar-bar.bar-foo + [[:sum :foo-foo]]) + (from :employee) + (group-by :foo-bar) + (sql/format :dialect :mysql)))))) From 6ca391c84ad44414ca0d55cb0f84fabd720813f6 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 9 May 2021 11:35:33 -0700 Subject: [PATCH 243/254] Update test-runner --- CHANGELOG.md | 3 +++ deps.edn | 8 +++----- run-tests.sh | 4 ++-- 3 files changed, 8 insertions(+), 7 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 63f1ef6..83be4f5 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.next in progress + * Update `test-runner`. + * 2.0.0-rc1 (for testing; 2021-05-06) * Fix #324 so that `insert-into` supports merging into another statement in all cases. * Fix #323 by supporting more than one SQL entity in `:on-conflict`. diff --git a/deps.edn b/deps.edn index 380ea0c..8102ff2 100644 --- a/deps.edn +++ b/deps.edn @@ -7,12 +7,10 @@ :master {:override-deps {org.clojure/clojure {:mvn/version "1.11.1-master-SNAPSHOT"}}} :test {:extra-paths ["test"]} :runner - {:extra-deps {com.cognitect/test-runner + {:extra-deps {io.github.cognitect-labs/test-runner {:git/url "https://github.com/cognitect-labs/test-runner" - :sha "b6b3193fcc42659d7e46ecd1884a228993441182"}} - :main-opts ["-m" "cognitect.test-runner" - ;"-d" "target/test-doc-blocks/test" - "-d" "test"]} + :sha "2d69f33d7980c3353b246c28f72ffeafbd9f2fab"}} + :exec-fn cognitect.test-runner.api/test} :cljs-runner {:extra-deps {olical/cljs-test-runner {:mvn/version "3.8.0"}} :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} diff --git a/run-tests.sh b/run-tests.sh index 9164ed7..ff668d6 100755 --- a/run-tests.sh +++ b/run-tests.sh @@ -11,7 +11,7 @@ then for v in 1.9 1.10 master do echo ==== Test Clojure $v ==== - clojure -M:test:runner:$v + clojure -X:test:runner:$v if test $? -ne 0 then exit 1 @@ -19,7 +19,7 @@ then done else echo ==== Test Clojure ==== - clojure -M:test:runner + clojure -X:test:runner fi else exit 1 From 07a4d9127d406dde58da95053a3d55044faff8dc Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sun, 9 May 2021 16:06:49 -0700 Subject: [PATCH 244/254] Update deps --- .github/workflows/test.yml | 2 +- deps.edn | 4 ++-- 2 files changed, 3 insertions(+), 3 deletions(-) diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index be44dec..6cdcd6a 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -17,7 +17,7 @@ jobs: - name: Setup Clojure uses: DeLaGuardo/setup-clojure@master with: - tools-deps: '1.10.3.814' + tools-deps: '1.10.3.822' - name: Run Tests run: sh run-tests.sh all - name: Check cljdoc.edn diff --git a/deps.edn b/deps.edn index 8102ff2..bb907e1 100644 --- a/deps.edn +++ b/deps.edn @@ -15,9 +15,9 @@ :main-opts ["-m" "cljs-test-runner.main"]} :readme {:extra-deps {seancorfield/readme {:mvn/version "1.0.16"}} :main-opts ["-m" "seancorfield.readme"]} - :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.4.0"}} + :eastwood {:extra-deps {jonase/eastwood {:mvn/version "0.4.2"}} :main-opts ["-m" "eastwood.lint" "{:source-paths,[\"src\"]}"]} - :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.211"}} + :jar {:replace-deps {com.github.seancorfield/depstar {:mvn/version "2.0.216"}} :exec-fn hf.depstar/jar :exec-args {:jar "honeysql.jar" :sync-pom true}} :install {:replace-deps {slipset/deps-deploy {:mvn/version "0.1.5"}} From 9c38554154732f792fe2f30599fa85cc91a3f937 Mon Sep 17 00:00:00 2001 From: Neil McCalum Date: Tue, 11 May 2021 01:07:34 +1200 Subject: [PATCH 245/254] format with opts, hyphen to under in function names, improve and relocate tests --- src/honey/sql.cljc | 15 +++++++-------- test/honey/sql/helpers_test.cljc | 24 ------------------------ test/honey/sql_test.cljc | 21 +++++++++++++++++++++ 3 files changed, 28 insertions(+), 32 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index b3b69d4..604d06e 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -153,6 +153,7 @@ (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) +(defn- -_ [x] (str/replace x "-" "_")) (defn- sqlize-value [x] (cond @@ -217,15 +218,13 @@ (let [c (name x)] (cond (= \% (first c)) (let [[f & args] (str/split (subs c 1) #"\.") - quoted-args (->> args - (map keyword) - (map format-entity))] - [(str (upper-case f) "(" (str/join "," quoted-args) ")")]) + quoted-args (map #(format-entity (keyword %) opts) args)] + [(str (upper-case (-_ f)) "(" (str/join ", " quoted-args) ")")]) (= \? (first c)) - (let [k (keyword (subs c 1))] - (if *inline* - [(sqlize-value (param-value k))] - ["?" (->param k)])) + (let [k (keyword (subs (-_ c) 1))] + (if *inline* + [(sqlize-value (param-value k))] + ["?" (->param k)])) :else [(format-entity x opts)]))) diff --git a/test/honey/sql/helpers_test.cljc b/test/honey/sql/helpers_test.cljc index 60e9a4d..33ea68c 100644 --- a/test/honey/sql/helpers_test.cljc +++ b/test/honey/sql/helpers_test.cljc @@ -866,27 +866,3 @@ {:with [[:a]], :insert-into [[:quux [:x :y]] {:select [:id], :from [:table]}]})))) - -(deftest quoting-:%-syntax - (testing "quoting of expressions in functions shouldn't depend on syntax" - (is (= [(str "SELECT `foo-bar`," - " COUNT(*)," - " COUNT(*)," - " SYSDATE()," - " SYSDATE()," - " AVG(`bar-bar`)," - " AVG(`bar-bar`,`bar-foo`)," - " SUM(`foo-foo`)" - " FROM `employee`" - " GROUP BY `foo-bar`")] - (-> (select :foo-bar - [[:count :*]] - :%count.* - :%sysdate - :%sysdate. - :%avg.bar-bar - :%avg.bar-bar.bar-foo - [[:sum :foo-foo]]) - (from :employee) - (group-by :foo-bar) - (sql/format :dialect :mysql)))))) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 489807b..ff12565 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -731,3 +731,24 @@ ORDER BY id = ? DESC (is (thrown-with-msg? ExceptionInfo #"does not match" (format {:where [:in :x :?y]} {:params {:y [nil]} :checking :strict}))))) + +(deftest quoting-:%-syntax + (testing "quoting of expressions in functions shouldn't depend on syntax" + (is (= ["SELECT SYSDATE()"] + (format {:select [[[:sysdate]]]}) + (format {:select :%sysdate}))) + (is (= ["SELECT COUNT(*)"] + (format {:select [[[:count :*]]]}) + (format {:select :%count.*}))) + (is (= ["SELECT AVERAGE(`foo-foo`)"] + (format {:select [[[:average :foo-foo]]]} :dialect :mysql) + (format {:select :%average.foo-foo} :dialect :mysql))) + (is (= ["SELECT GREATER(`foo-foo`, `bar-bar`)"] + (format {:select [[[:greater :foo-foo :bar-bar]]]} :dialect :mysql) + (format {:select :%greater.foo-foo.bar-bar} :dialect :mysql))) + (is (= ["SELECT MIXED_KEBAB(`yum-yum`)"] + #_(format {:select [[[:mixed-kebab :yum-yum]]]} :dialect :mysql) + (format {:select :%mixed-kebab.yum-yum} :dialect :mysql))) + (is (= ["SELECT RANSOM(`NoTe`)"] + (format {:select [[[:ransom :NoTe]]]} :dialect :mysql) + (format {:select :%ransom.NoTe} :dialect :mysql))))) From 12bfa3296268d809277aa6102c2d02159dea75f7 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 11:55:28 -0700 Subject: [PATCH 246/254] Addresses #326 by no longer dropping parameters --- src/honey/sql.cljc | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4514180..76e09a8 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -453,7 +453,9 @@ (into params params-j)] (let [[sql & params'] (when e (format-expr e))] [(cond-> sqls e (conj "ON" sql)) - (into params params')])))) + (-> params + (into params-j) + (into params'))])))) [[] []] (partition 2 clauses))] (into [(str/join " " sqls)] params))) From 572984a45d2f8ee5a0dac9221b932a8994f36091 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 12:05:07 -0700 Subject: [PATCH 247/254] Addresses #326 by allowing ON/USING to be optional --- src/honey/sql.cljc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 76e09a8..0890048 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -457,7 +457,7 @@ (into params-j) (into params'))])))) [[] []] - (partition 2 clauses))] + (partition-all 2 clauses))] (into [(str/join " " sqls)] params))) (def ^:private join-by-aliases From 819c6e7c1920f8dc537a5669bb0a44634e1e3a67 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 12:37:07 -0700 Subject: [PATCH 248/254] Additional work on #325; update CHANGELOG --- CHANGELOG.md | 5 +++-- src/honey/sql.cljc | 11 +++++++---- 2 files changed, 10 insertions(+), 6 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index eb66033..46d7a83 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,9 +1,10 @@ # Changes * 2.0.next in progress - * Update `test-runner`. + * Address #326 by allowing `ON`/`USING` to be optional and not dropping parameters on the floor. _[still needs tests to be written!]_ + * Fix #325 by making the `%` function call syntax respect `:quoted true` and/or `:dialect` options, and also allowing for qualified column names _[some additional tests needed plus likely documentation updates]_. (PR from @lognush) * Add `:quoted-snake true` option to force conversion from kebab-case to snake_case when `:quoted true` or a `:dialect` is specified to `format`. - * TBD `%` function syntax may respect `:quoted true` or a `:dialect` is specified to `format` (awaiting PR). + * Update `test-runner`. * 2.0.0-rc1 (for testing; 2021-05-06) * Fix #324 so that `insert-into` supports merging into another statement in all cases. diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 4e391cd..2dedaec 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -153,7 +153,6 @@ (defn- namespace-_ [x] (some-> (namespace x) (str/replace "-" "_"))) (defn- name-_ [x] (str/replace (name x) "-" "_")) -(defn- -_ [x] (str/replace x "-" "_")) (defn- sqlize-value [x] (cond @@ -215,13 +214,17 @@ (fn [fk _] (param-value (fk)))})) (defn- format-var [x & [opts]] - (let [c (name x)] + ;; rather than name/namespace, we want to allow + ;; for multiple / in the %fun.call case so that + ;; qualified column names can be used: + (let [c (cond-> (str x) (keyword? x) (subs 1))] (cond (= \% (first c)) (let [[f & args] (str/split (subs c 1) #"\.") quoted-args (map #(format-entity (keyword %) opts) args)] - [(str (upper-case (-_ f)) "(" (str/join ", " quoted-args) ")")]) + [(str (upper-case (str/replace f "-" "_")) + "(" (str/join ", " quoted-args) ")")]) (= \? (first c)) - (let [k (keyword (subs (-_ c) 1))] + (let [k (keyword (subs c 1))] (if *inline* [(sqlize-value (param-value k))] ["?" (->param k)])) From 9e0b31bbd943340fb64ffa2637ef473c2dd22221 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 22:44:57 -0700 Subject: [PATCH 249/254] Fixes #325 Fixes #326 adds tests/docs --- CHANGELOG.md | 4 ++-- doc/getting-started.md | 7 +++++++ test/honey/sql_test.cljc | 35 +++++++++++++++++++++++++++++++++-- 3 files changed, 42 insertions(+), 4 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 46d7a83..6931b8d 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,8 +1,8 @@ # Changes * 2.0.next in progress - * Address #326 by allowing `ON`/`USING` to be optional and not dropping parameters on the floor. _[still needs tests to be written!]_ - * Fix #325 by making the `%` function call syntax respect `:quoted true` and/or `:dialect` options, and also allowing for qualified column names _[some additional tests needed plus likely documentation updates]_. (PR from @lognush) + * Fix #326 by allowing `ON`/`USING` to be optional and not dropping parameters on the floor. + * Fix #325 by making the `%` function call syntax respect `:quoted true` and/or `:dialect` options, and also allowing for qualified column names. (PR from @lognush) * Add `:quoted-snake true` option to force conversion from kebab-case to snake_case when `:quoted true` or a `:dialect` is specified to `format`. * Update `test-runner`. diff --git a/doc/getting-started.md b/doc/getting-started.md index e7e3615..f4e63b3 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -136,6 +136,13 @@ are split at `.` and turned into function calls: %f.a.b ;=> F(a,b) ``` +If you need to reference a table or alias for a column, you can use +qualified names in a function invocation: + +```clojure +%max.foo/bar ;=> MAX(foo.bar) +``` + ## SQL Parameters As indicated in the preceding sections, values found in the DSL data structure diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index ff12565..3a500a8 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -1,4 +1,4 @@ -;; copyright (c) sean corfield, all rights reserved +;; copyright (c) 2021 sean corfield, all rights reserved (ns honey.sql-test (:refer-clojure :exclude [format]) @@ -747,8 +747,39 @@ ORDER BY id = ? DESC (format {:select [[[:greater :foo-foo :bar-bar]]]} :dialect :mysql) (format {:select :%greater.foo-foo.bar-bar} :dialect :mysql))) (is (= ["SELECT MIXED_KEBAB(`yum-yum`)"] - #_(format {:select [[[:mixed-kebab :yum-yum]]]} :dialect :mysql) (format {:select :%mixed-kebab.yum-yum} :dialect :mysql))) + (is (= ["SELECT MIXED_KEBAB(`yum_yum`)"] + (format {:select :%mixed-kebab.yum-yum} :dialect :mysql :quoted-snake true))) + ;; qualifier is always - -> _ converted: + (is (= ["SELECT MIXED_KEBAB(`yum_yum`.`bar-bar`, `a_b`.`c-d`)"] + (format {:select :%mixed-kebab.yum-yum/bar-bar.a-b/c-d} :dialect :mysql))) + ;; name is only - -> _ converted when snake_case requested: + (is (= ["SELECT MIXED_KEBAB(`yum_yum`.`bar_bar`, `a_b`.`c_d`)"] + (format {:select :%mixed-kebab.yum-yum/bar-bar.a-b/c-d} :dialect :mysql :quoted-snake true))) (is (= ["SELECT RANSOM(`NoTe`)"] (format {:select [[[:ransom :NoTe]]]} :dialect :mysql) (format {:select :%ransom.NoTe} :dialect :mysql))))) + +(deftest join-without-on-using + ;; essentially issue 326 + (testing "join does not need on or using" + (is (= ["SELECT foo FROM bar INNER JOIN quux"] + (format {:select :foo + :from :bar + :join [:quux]})))) + (testing "join on select with parameters" + (is (= ["SELECT foo FROM bar INNER JOIN (SELECT a FROM b WHERE id = ?) WHERE id = ?" 123 456] + (format {:select :foo + :from :bar + :join [{:select :a :from :b :where [:= :id 123]}] + :where [:= :id 456]}))) + (is (= ["SELECT foo FROM bar INNER JOIN (SELECT a FROM b WHERE id = ?) AS x WHERE id = ?" 123 456] + (format {:select :foo + :from :bar + :join [[{:select :a :from :b :where [:= :id 123]} :x]] + :where [:= :id 456]}))) + (is (= ["SELECT foo FROM bar INNER JOIN (SELECT a FROM b WHERE id = ?) AS x ON y WHERE id = ?" 123 456] + (format {:select :foo + :from :bar + :join [[{:select :a :from :b :where [:= :id 123]} :x] :y] + :where [:= :id 456]}))))) From fe4be6cca65decb081fec9a981998763b03832f5 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 22:46:36 -0700 Subject: [PATCH 250/254] Make test cljs-compatible --- test/honey/sql_test.cljc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 3a500a8..ae2109a 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -752,10 +752,10 @@ ORDER BY id = ? DESC (format {:select :%mixed-kebab.yum-yum} :dialect :mysql :quoted-snake true))) ;; qualifier is always - -> _ converted: (is (= ["SELECT MIXED_KEBAB(`yum_yum`.`bar-bar`, `a_b`.`c-d`)"] - (format {:select :%mixed-kebab.yum-yum/bar-bar.a-b/c-d} :dialect :mysql))) + (format {:select (keyword "%mixed-kebab.yum-yum/bar-bar.a-b/c-d")} :dialect :mysql))) ;; name is only - -> _ converted when snake_case requested: (is (= ["SELECT MIXED_KEBAB(`yum_yum`.`bar_bar`, `a_b`.`c_d`)"] - (format {:select :%mixed-kebab.yum-yum/bar-bar.a-b/c-d} :dialect :mysql :quoted-snake true))) + (format {:select (keyword "%mixed-kebab.yum-yum/bar-bar.a-b/c-d")} :dialect :mysql :quoted-snake true))) (is (= ["SELECT RANSOM(`NoTe`)"] (format {:select [[[:ransom :NoTe]]]} :dialect :mysql) (format {:select :%ransom.NoTe} :dialect :mysql))))) From 81fda8592deefef871fd2b11baa63f03f31030e0 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 10 May 2021 22:51:41 -0700 Subject: [PATCH 251/254] Prep for 2.0.0 RC 2 --- CHANGELOG.md | 2 +- README.md | 2 +- doc/differences-from-1-x.md | 4 ++-- doc/general-reference.md | 2 +- doc/getting-started.md | 8 ++++---- pom.xml | 4 ++-- 6 files changed, 11 insertions(+), 11 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 6931b8d..2b29836 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,6 +1,6 @@ # Changes -* 2.0.next in progress +* 2.0.0-rc2 (for testing; 2021-05-10) * Fix #326 by allowing `ON`/`USING` to be optional and not dropping parameters on the floor. * Fix #325 by making the `%` function call syntax respect `:quoted true` and/or `:dialect` options, and also allowing for qualified column names. (PR from @lognush) * Add `:quoted-snake true` option to force conversion from kebab-case to snake_case when `:quoted true` or a `:dialect` is specified to `format`. diff --git a/README.md b/README.md index 1f26a21..6e95c3f 100644 --- a/README.md +++ b/README.md @@ -4,7 +4,7 @@ SQL as Clojure data structures. Build queries programmatically -- even at runtim ## Build -[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-rc1)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1) +[![Clojars Project](https://clojars.org/com.github.seancorfield/honeysql/latest-version.svg)](https://clojars.org/com.github.seancorfield/honeysql) [![cljdoc badge](https://cljdoc.org/badge/com.github.seancorfield/honeysql?2.0.0-rc2)](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc2) Once the prerelease testing is complete, this project will follow the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository. diff --git a/doc/differences-from-1-x.md b/doc/differences-from-1-x.md index 365c159..e380668 100644 --- a/doc/differences-from-1-x.md +++ b/doc/differences-from-1-x.md @@ -49,7 +49,7 @@ Supported Clojure versions: 1.7 and later. ```clojure ;; in deps.edn: -com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc1"} +com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc2"} ;; in use: (ns my.project @@ -85,7 +85,7 @@ The `:quoting ` option has superseded by the new dialect machinery and Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`. The following options are no longer supported: -* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). If you want dashed-names to be converted to snake_case when `:quoted true`, you also need to specify `:quoted-snake true`. _[New in 2.0.next]_ +* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). If you want dashed-names to be converted to snake_case when `:quoted true`, you also need to specify `:quoted-snake true`. * `:allow-namespaced-names?` -- this supported `foo/bar` column names in SQL which I'd like to discourage. * `:namespace-as-table?` -- this is the default in 2.x: `:foo/bar` will be treated as `foo.bar` which is more in keeping with `next.jdbc`. * `:parameterizer` -- this would add a lot of complexity to the formatting engine and I do not know how widely it was used (especially in its arbitrarily extensible form). diff --git a/doc/general-reference.md b/doc/general-reference.md index cce936a..6c460ed 100644 --- a/doc/general-reference.md +++ b/doc/general-reference.md @@ -114,6 +114,6 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc2/api/honey.sql.helpers) namespace. If you're migrating to HoneySQL 2.x, this [overview of differences between 1.x and 2.x](differences-from-1-x.md) should help. diff --git a/doc/getting-started.md b/doc/getting-started.md index f4e63b3..949d6a1 100644 --- a/doc/getting-started.md +++ b/doc/getting-started.md @@ -9,13 +9,13 @@ data to a SQL statement (string) and any parameters it needs. For the Clojure CLI, add the following dependency to your `deps.edn` file: ```clojure - com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc1"} + com.github.seancorfield/honeysql {:mvn/version "2.0.0-rc2"} ``` For Leiningen, add the following dependency to your `project.clj` file: ```clojure - [com.github.seancorfield/honeysql "2.0.0-rc1"] + [com.github.seancorfield/honeysql "2.0.0-rc2"] ``` HoneySQL produces SQL statements but does not execute them. @@ -325,7 +325,7 @@ are treated as an error and an exception is thrown. If `:checking :strict` is specified, certain dubious constructs -- such as `IN` with a collection containing `NULL` values -- are also treated as an error and an exception is thrown. It is expected that this feature will be expanded over time -to help avoid generating illegal SQL. _[New in version 2.0.0-rc1]_ +to help avoid generating illegal SQL. `format` accepts options as either a single hash map argument or as named arguments (alternating keys and values). If you are using @@ -342,7 +342,7 @@ section. The full list of "special syntax" functions is documented in the [Special Syntax](special-syntax.md) section. The best documentation for the helper functions is in the -[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc1/api/honey.sql.helpers) namespace. +[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/2.0.0-rc2/api/honey.sql.helpers) namespace. More detail about certain core HoneySQL functionality can be found in the [Reference documentation](general-reference.md). If you're migrating to HoneySQL 2.x, this [overview of differences diff --git a/pom.xml b/pom.xml index 2f661a7..96e19a9 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 com.github.seancorfield honeysql - 2.0.0-rc1 + 2.0.0-rc2 honeysql SQL as Clojure data structures. https://github.com/seancorfield/honeysql @@ -25,7 +25,7 @@ https://github.com/seancorfield/honeysql scm:git:git://github.com/seancorfield/honeysql.git scm:git:ssh://git@github.com/seancorfield/honeysql.git - v2.0.0-rc1 + v2.0.0-rc2 From 9f5b552ad0b4812a1af712d918872f8df775128c Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 11 May 2021 18:32:43 -0700 Subject: [PATCH 252/254] Add GH Actions CI badge for v2 --- README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/README.md b/README.md index 6e95c3f..5959102 100644 --- a/README.md +++ b/README.md @@ -1,4 +1,4 @@ -# Honey SQL [![CircleCI](https://circleci.com/gh/seancorfield/honeysql/tree/v2.svg?style=svg)](https://circleci.com/gh/seancorfield/honeysql/tree/v2) +# Honey SQL [![Clojure CI](https://github.com/seancorfield/honeysql/actions/workflows/test.yml/badge.svg?branch=v2)](https://github.com/seancorfield/honeysql/actions/workflows/test.yml) [![CircleCI](https://circleci.com/gh/seancorfield/honeysql/tree/v2.svg?style=svg)](https://circleci.com/gh/seancorfield/honeysql/tree/v2) SQL as Clojure data structures. Build queries programmatically -- even at runtime -- without having to bash strings together. From 29a060d4227916480edbac96914391287641c0b8 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Tue, 11 May 2021 21:10:32 -0700 Subject: [PATCH 253/254] Update CircleCI CLI --- .circleci/config.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.circleci/config.yml b/.circleci/config.yml index 6046d5c..0d575ad 100644 --- a/.circleci/config.yml +++ b/.circleci/config.yml @@ -3,7 +3,7 @@ jobs: build: working_directory: ~/honeysql docker: - - image: circleci/clojure:openjdk-11-tools-deps-1.10.2.774 + - image: circleci/clojure:openjdk-11-tools-deps-1.10.3.822 steps: - checkout - restore_cache: From 52308d484f11ac55a94774abf40ebcb14973c525 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Mon, 17 May 2021 10:40:19 -0700 Subject: [PATCH 254/254] Support PostgreSQL && array operator --- CHANGELOG.md | 3 +++ src/honey/sql.cljc | 4 ++-- 2 files changed, 5 insertions(+), 2 deletions(-) diff --git a/CHANGELOG.md b/CHANGELOG.md index 2b29836..1301349 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,5 +1,8 @@ # Changes +* 2.0.next in progress + * Support PostgreSQL's `&&` operator. + * 2.0.0-rc2 (for testing; 2021-05-10) * Fix #326 by allowing `ON`/`USING` to be optional and not dropping parameters on the floor. * Fix #325 by making the `%` function call syntax respect `:quoted true` and/or `:dialect` options, and also allowing for qualified column names. (PR from @lognush) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 2dedaec..50c65f0 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -920,7 +920,7 @@ (def ^:private infix-ops (-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "<->" - "like" "not-like" "regexp" + "like" "not-like" "regexp" "&&" "ilike" "not-ilike" "similar-to" "not-similar-to" "is" "is-not" "not=" "!=" "regex"} (into (map str "+-*%|&^=<>")) @@ -931,7 +931,7 @@ (atom))) (def ^:private op-ignore-nil (atom #{:and :or})) -(def ^:private op-variadic (atom #{:and :or :+ :* :||})) +(def ^:private op-variadic (atom #{:and :or :+ :* :|| :&&})) (defn- unwrap [x opts] (if-let [m (meta x)]