From c00fbffe30398ea70be6c36e277e3df9ad265902 Mon Sep 17 00:00:00 2001 From: Sean Corfield Date: Sat, 6 Feb 2021 09:00:46 -0800 Subject: [PATCH] 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