Fixes #284 by adding lateral expression syntax
This commit is contained in:
parent
82ee465820
commit
cff1e5b43c
5 changed files with 66 additions and 4 deletions
|
|
@ -9,6 +9,7 @@
|
||||||
* Add tests to confirm #299 does not affect v2.
|
* 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).
|
* 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 #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.0 changes (porting #283 to v2).
|
||||||
* Fix #280 by adding `:escape` as special syntax for regular expression patterns.
|
* 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.
|
* Fix #277 by adding `:join-by`/`join-by` so that you can have multiple `JOIN`'s in a specific order.
|
||||||
|
|
|
||||||
|
|
@ -98,6 +98,11 @@ that represents a time unit. Produces an `INTERVAL` expression:
|
||||||
;;=> ["DATE_ADD(NOW(), INTERVAL ? DAYS)" 30]
|
;;=> ["DATE_ADD(NOW(), INTERVAL ? DAYS)" 30]
|
||||||
```
|
```
|
||||||
|
|
||||||
|
## lateral
|
||||||
|
|
||||||
|
Accepts a single argument that can be a (`SELECT`) clause or
|
||||||
|
a (function call) expression.
|
||||||
|
|
||||||
## lift
|
## lift
|
||||||
|
|
||||||
Used to wrap a Clojure value that should be passed as a
|
Used to wrap a Clojure value that should be passed as a
|
||||||
|
|
|
||||||
|
|
@ -111,6 +111,10 @@
|
||||||
#?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US))))
|
#?(:clj (fn [^String s] (.. s toString (toUpperCase (java.util.Locale/US))))
|
||||||
:cljs str/upper-case))
|
:cljs str/upper-case))
|
||||||
|
|
||||||
|
(def ^:private keep-hyphen
|
||||||
|
"The set of symbols that should not have `-` replaced by space."
|
||||||
|
#{"-" "<->"})
|
||||||
|
|
||||||
(defn sql-kw
|
(defn sql-kw
|
||||||
"Given a keyword, return a SQL representation of it as a string.
|
"Given a keyword, return a SQL representation of it as a string.
|
||||||
|
|
||||||
|
|
@ -120,7 +124,7 @@
|
||||||
Any namespace qualifier is ignored."
|
Any namespace qualifier is ignored."
|
||||||
[k]
|
[k]
|
||||||
(-> k (name) (upper-case)
|
(-> 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
|
(defn- sym->kw
|
||||||
"Given a symbol, produce a keyword, retaining the namespace
|
"Given a symbol, produce a keyword, retaining the namespace
|
||||||
|
|
@ -841,7 +845,7 @@
|
||||||
:regex :regexp})
|
:regex :regexp})
|
||||||
|
|
||||||
(def ^:private infix-ops
|
(def ^:private infix-ops
|
||||||
(-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||"
|
(-> #{"mod" "and" "or" "xor" "<>" "<=" ">=" "||" "<->"
|
||||||
"like" "not-like" "regexp"
|
"like" "not-like" "regexp"
|
||||||
"ilike" "not-ilike" "similar-to" "not-similar-to"
|
"ilike" "not-ilike" "similar-to" "not-similar-to"
|
||||||
"is" "is-not" "not=" "!=" "regex"}
|
"is" "is-not" "not=" "!=" "regex"}
|
||||||
|
|
@ -988,6 +992,13 @@
|
||||||
(fn [_ [n units]]
|
(fn [_ [n units]]
|
||||||
(let [[sql & params] (format-expr n)]
|
(let [[sql & params] (format-expr n)]
|
||||||
(into [(str "INTERVAL " sql " " (sql-kw units))] params)))
|
(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
|
:lift
|
||||||
(fn [_ [x]]
|
(fn [_ [x]]
|
||||||
(if *inline*
|
(if *inline*
|
||||||
|
|
|
||||||
|
|
@ -636,6 +636,19 @@
|
||||||
[& args]
|
[& args]
|
||||||
(into [:composite] 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:
|
;; to make this easy to use in a select, wrap it so it becomes a function:
|
||||||
(defn over
|
(defn over
|
||||||
"Accepts any number of OVER clauses, each of which
|
"Accepts any number of OVER clauses, each of which
|
||||||
|
|
@ -702,5 +715,5 @@
|
||||||
|
|
||||||
#?(:clj
|
#?(:clj
|
||||||
(assert (= (clojure.core/set (conj @@#'honey.sql/base-clause-order
|
(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*)))))))
|
(clojure.core/set (map keyword (keys (ns-publics *ns*)))))))
|
||||||
|
|
|
||||||
|
|
@ -10,7 +10,7 @@
|
||||||
create-materialized-view drop-view drop-materialized-view
|
create-materialized-view drop-view drop-materialized-view
|
||||||
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 from full-join
|
||||||
group-by having insert-into
|
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
|
on-duplicate-key-update
|
||||||
order-by over partition-by refresh-materialized-view
|
order-by over partition-by refresh-materialized-view
|
||||||
rename-column rename-table returning right-join
|
rename-column rename-table returning right-join
|
||||||
|
|
@ -95,6 +95,38 @@
|
||||||
(from :bar)
|
(from :bar)
|
||||||
(order-by :quux)))))))
|
(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
|
(deftest join-by-test
|
||||||
(testing "Natural JOIN orders"
|
(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"]
|
(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"]
|
||||||
|
|
|
||||||
Loading…
Reference in a new issue