From 30e554f31c5e7c535ae61d1c35aed00fef0c9de7 Mon Sep 17 00:00:00 2001 From: Ike Mawira Date: Thu, 22 Sep 2022 19:40:15 +0300 Subject: [PATCH 1/2] Allow `with expr AS ident` syntax in WITH clause --- src/honey/sql.cljc | 28 +++++++++++++++++++--------- 1 file changed, 19 insertions(+), 9 deletions(-) diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 3f4081ae..705bc479 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -159,6 +159,11 @@ [] (= :sqlserver (:dialect *dialect*))) +(defn- clickhouse? + "Helper to detect if Clickhouse is the current dialect." + [] + (= :clickhouse (:dialect *dialect*))) + ;; 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 @@ -552,15 +557,20 @@ ;; or just entity, as far as I can tell... (let [[sqls params] (reduce-sql - (map - (fn [[x expr :as with]] - (let [[sql & params] (format-with-part x) - [sql' & params'] (format-dsl expr)] - ;; according to docs, CTE should _always_ be wrapped: - (cond-> [(str sql " " (as-fn with) " " (str "(" sql' ")"))] - params (into params) - params' (into params')))) - xs))] + (map + (fn [[x expr :as with]] + (let [[sql & params] (format-with-part x) + [sql' & params'] (if (and (clickhouse?) ;;in clickhouse the expression can be + (not (map? expr))) ;; a string arranged as `with expr as ident` + (format-expr expr) + (format-dsl expr))] + ;; according to docs, CTE should _always_ be wrapped: + (cond-> [(if (and (clickhouse?) (not (map? expr))) + (str sql' " AS " sql) + (str sql " " (as-fn with) " " (str "(" sql' ")")))] + params (into params) + params' (into params')))) + xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-selector [k xs] From 73d36ab2b5839a5ee9d0b273175b4d4d0f09e08a Mon Sep 17 00:00:00 2001 From: Ike Mawira Date: Fri, 23 Sep 2022 16:54:30 +0300 Subject: [PATCH 2/2] Update docs and tests for WITH clause --- doc/clause-reference.md | 31 ++++++++++++++++++++++++++++++- src/honey/sql.cljc | 31 ++++++++++++++----------------- test/honey/sql_test.cljc | 25 ++++++++++++++++++++++++- 3 files changed, 68 insertions(+), 19 deletions(-) diff --git a/doc/clause-reference.md b/doc/clause-reference.md index 686bdfb0..41a4eb1b 100644 --- a/doc/clause-reference.md +++ b/doc/clause-reference.md @@ -297,7 +297,8 @@ order they would appear in a valid SQL statement). 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. +a result set name (or description) and either of; a basic SQL +statement, a string, a keyword or a symbol. 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. @@ -310,6 +311,34 @@ user=> (sql/format '{with ((stuff {select (:*) from (foo)}), ["WITH stuff AS (SELECT * FROM foo), nonsense AS (SELECT * FROM bar) SELECT foo.id, bar.name FROM stuff, nonsense WHERE status = ?" 0] ``` +When the expression is a basic SQL statement in any of the pairs, +the resulting syntax of the pair is `with ident AS expr` as shown above. +However, when the expression is a string, a keyword or a symbol, the resulting +syntax of the pair is of the form `with expr AS ident` like this: + +```clojure +user=> (sql/format '{with ((ts_upper_bound "2019-08-01 15:23:00")) + select :* + from (hits) + where (= EventDate ts_upper_bound)}) +["WITH ? AS ts_upper_bound SELECT * FROM hits WHERE EventDate = ts_upper_bound" "2019-08-01 15:23:00"] +``` + +The syntax only varies for each pair and so you can use both SQL statements +and keywords/strings/symbols in the same WITH clause like this: + +```clojure +user=> (sql/format '{with ((ts_upper_bound "2019-08-01 15:23:00") + (review :awesome) + (stuff {select (:*) from (songs)})) + select :* + from (hits, stuff) + where (and (= EventDate ts_upper_bound) + (= EventReview review))}) +["WITH ? AS ts_upper_bound, awesome AS review, stuff AS (SELECT * FROM songs) SELECT * FROM hits, stuff WHERE (EventDate = ts_upper_bound) AND (EventReview = review)" + "2019-08-01 15:23:00"] +``` + You can specify a list of columns for the CTE like this: ```clojure diff --git a/src/honey/sql.cljc b/src/honey/sql.cljc index 705bc479..8680993c 100644 --- a/src/honey/sql.cljc +++ b/src/honey/sql.cljc @@ -159,11 +159,6 @@ [] (= :sqlserver (:dialect *dialect*))) -(defn- clickhouse? - "Helper to detect if Clickhouse is the current dialect." - [] - (= :clickhouse (:dialect *dialect*))) - ;; 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 @@ -557,20 +552,22 @@ ;; or just entity, as far as I can tell... (let [[sqls params] (reduce-sql - (map - (fn [[x expr :as with]] - (let [[sql & params] (format-with-part x) - [sql' & params'] (if (and (clickhouse?) ;;in clickhouse the expression can be - (not (map? expr))) ;; a string arranged as `with expr as ident` - (format-expr expr) - (format-dsl expr))] + (map + (fn [[x expr :as with]] + (let [[sql & params] (format-with-part x) + non-query-expr? (or (ident? expr) (string? expr)) + [sql' & params'] (if non-query-expr? + (format-expr expr) + (format-dsl expr))] + (if non-query-expr? + (cond-> [(str sql' " AS " sql)] + params' (into params') + params (into params)) ;; according to docs, CTE should _always_ be wrapped: - (cond-> [(if (and (clickhouse?) (not (map? expr))) - (str sql' " AS " sql) - (str sql " " (as-fn with) " " (str "(" sql' ")")))] + (cond-> [(str sql " " (as-fn with) " " (str "(" sql' ")"))] params (into params) - params' (into params')))) - xs))] + params' (into params'))))) + xs))] (into [(str (sql-kw k) " " (str/join ", " sqls))] params))) (defn- format-selector [k xs] diff --git a/test/honey/sql_test.cljc b/test/honey/sql_test.cljc index 686e7138..6f536132 100644 --- a/test/honey/sql_test.cljc +++ b/test/honey/sql_test.cljc @@ -144,7 +144,30 @@ {: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]))) + ["WITH static (a, b, c) AS (VALUES (?, ?, NULL), (?, ?, ?)) SELECT * FROM static" 1 2 4 5 6])) + (testing "When the expression passed to WITH clause is a string or `ident?` the syntax of WITH clause is `with expr AS ident`" + (is (= (format + {:with [[:ts_upper_bound "2019-08-01 15:23:00"]] + :select [:*] + :from [:hits] + :where [:= :EventDate :ts_upper_bound]}) + ["WITH ? AS ts_upper_bound SELECT * FROM hits WHERE EventDate = ts_upper_bound" "2019-08-01 15:23:00"])) + (is (= (format + {:with [[:ts_upper_bound :2019-08-01]] + :select [:*] + :from [:hits] + :where [:= :EventDate :ts_upper_bound]}) + ["WITH 2019_08_01 AS ts_upper_bound SELECT * FROM hits WHERE EventDate = ts_upper_bound"]))) + (testing "Mixing the syntax of WITH in the resulting clause" + (is (= (format + {:with [[:ts_upper_bound "2019-08-01 15:23:00"] + [:stuff {:select [:*] + :from [:songs]}]] + :select [:*] + :from [:hits :stuff] + :where [:= :EventDate :ts_upper_bound]}) + ["WITH ? AS ts_upper_bound, stuff AS (SELECT * FROM songs) SELECT * FROM hits, stuff WHERE EventDate = ts_upper_bound" + "2019-08-01 15:23:00"])))) (deftest insert-into (is (= (format {:insert-into :foo})