Update docs and tests for WITH clause
This commit is contained in:
parent
30e554f31c
commit
73d36ab2b5
3 changed files with 68 additions and 19 deletions
|
|
@ -297,7 +297,8 @@ order they would appear in a valid SQL statement).
|
||||||
|
|
||||||
These provide CTE support for SQL Server. The argument to
|
These provide CTE support for SQL Server. The argument to
|
||||||
`:with` (or `:with-recursive`) is a sequences of pairs, each of
|
`: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)
|
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.
|
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]
|
["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:
|
You can specify a list of columns for the CTE like this:
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
|
|
|
||||||
|
|
@ -159,11 +159,6 @@
|
||||||
[]
|
[]
|
||||||
(= :sqlserver (:dialect *dialect*)))
|
(= :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.toUpperCase() or `str/upper-case` for that matter converts the
|
||||||
;; string to uppercase for the DEFAULT LOCALE. Normally this does what you'd
|
;; 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
|
;; 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...
|
;; or just entity, as far as I can tell...
|
||||||
(let [[sqls params]
|
(let [[sqls params]
|
||||||
(reduce-sql
|
(reduce-sql
|
||||||
(map
|
(map
|
||||||
(fn [[x expr :as with]]
|
(fn [[x expr :as with]]
|
||||||
(let [[sql & params] (format-with-part x)
|
(let [[sql & params] (format-with-part x)
|
||||||
[sql' & params'] (if (and (clickhouse?) ;;in clickhouse the expression can be
|
non-query-expr? (or (ident? expr) (string? expr))
|
||||||
(not (map? expr))) ;; a string arranged as `with expr as ident`
|
[sql' & params'] (if non-query-expr?
|
||||||
(format-expr expr)
|
(format-expr expr)
|
||||||
(format-dsl 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:
|
;; according to docs, CTE should _always_ be wrapped:
|
||||||
(cond-> [(if (and (clickhouse?) (not (map? expr)))
|
(cond-> [(str sql " " (as-fn with) " " (str "(" sql' ")"))]
|
||||||
(str sql' " AS " sql)
|
|
||||||
(str sql " " (as-fn with) " " (str "(" sql' ")")))]
|
|
||||||
params (into params)
|
params (into params)
|
||||||
params' (into params'))))
|
params' (into params')))))
|
||||||
xs))]
|
xs))]
|
||||||
(into [(str (sql-kw k) " " (str/join ", " sqls))] params)))
|
(into [(str (sql-kw k) " " (str/join ", " sqls))] params)))
|
||||||
|
|
||||||
(defn- format-selector [k xs]
|
(defn- format-selector [k xs]
|
||||||
|
|
|
||||||
|
|
@ -144,7 +144,30 @@
|
||||||
{:values [[1 2] [4 5 6]]}]]
|
{:values [[1 2] [4 5 6]]}]]
|
||||||
:select [:*]
|
:select [:*]
|
||||||
:from [:static]})
|
: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
|
(deftest insert-into
|
||||||
(is (= (format {:insert-into :foo})
|
(is (= (format {:insert-into :foo})
|
||||||
|
|
|
||||||
Loading…
Reference in a new issue