Addresses #310 by adding filter, order-by, within-group syntax
This commit is contained in:
parent
bbc0ac8500
commit
50fd829752
6 changed files with 151 additions and 12 deletions
|
|
@ -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]
|
||||
|
|
|
|||
|
|
@ -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
|
||||
|
|
|
|||
|
|
@ -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.
|
||||
|
|
|
|||
|
|
@ -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
|
||||
|
|
|
|||
|
|
@ -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))))))
|
||||
|
|
|
|||
|
|
@ -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]))))
|
||||
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]))))
|
||||
|
|
|
|||
Loading…
Reference in a new issue