Addresses #293 by adding over, partition-by, and window

This commit is contained in:
Sean Corfield 2021-02-10 16:25:31 -08:00
parent 5318c184e6
commit e157aec976
5 changed files with 120 additions and 7 deletions

View file

@ -312,6 +312,59 @@ user=> (sql/format '{select (*) from (table)
The `:having` clause works identically to `:where` above
but is rendered into the SQL later in precedence order.
## window, partition-by (and over)
`:window` accepts a pair of SQL entity (the window name)
and the window "function" as a SQL clause (a hash map).
`:partition-by` accepts the same arguments as `:select` above
(even though the allowable SQL generated is much more restrictive).
These are expected to be used with the `:over` expression (special syntax).
```clojure
user=> (sql/format {:select [:id
[[:over
[[:avg :salary]
{:partition-by [:department]
:order-by [:designation]}
:Average]
[[:max :salary]
:w
:MaxSalary]]]]
:from [:employee]
:window [:w {:partition-by [:department]}]})
["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"]
;; easier to write with helpers (and easier to read!):
user=> (sql/format (-> (select :id
(over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average]
[[:max :salary] :w :MaxSalary]))
(from :employee)
(window :w (partition-by :department))))
["SELECT id, AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average, MAX(salary) OVER w AS MaxSalary FROM employee WINDOW w AS (PARTITION BY department)"]
```
The window function in the `:over` expression may be `{}` or `nil`:
```clojure
user=> (sql/format {:select [:id
[[:over
[[:avg :salary]
{}
:Average]
[[:max :salary]
nil
:MaxSalary]]]]
:from [:employee]})
["SELECT id, AVG(salary) OVER () AS Average, MAX(salary) OVER () AS MaxSalary FROM employee"]
;; easier to write with helpers (and easier to read!):
user=> (sql/format (-> (select :id
(over [[:avg :salary] {} :Average]
[[:max :salary] nil :MaxSalary]))
(from :employee)))
["SELECT id, AVG(salary) OVER () AS Average, MAX(salary) OVER () AS MaxSalary FROM employee"]
```
## order-by
`:order-by` accepts a sequence of one or more ordering

View file

@ -128,6 +128,20 @@ in front of it:
;;=> ["NOT x = ?" 42]
```
## over
This is intended to be used with the `:window` and `:partition-by` clauses.
`:over` takes any number of window expressions which are either pairs or triples
that have an aggregation expression, a window function, and an optional alias.
The window function may either be a SQL entity (named in a `:window` clause)
or a SQL clause that describes the window (e.g., using `:partition-by` and/or `:order-by`).
Since a function call (using `:over`) needs to be wrapped in a sequence for a
`:select` clause, it is usually easier to use the `over` helper function
to construct this expression.
## param
Used to identify a named parameter in a SQL expression

View file

@ -41,7 +41,9 @@
:columns :set :from :using
:join :left-join :right-join :inner-join :outer-join :full-join
:cross-join
:where :group-by :having :order-by :limit :offset :for :values
:where :group-by :having
:window :partition-by
:order-by :limit :offset :for :values
:on-conflict :on-constraint :do-nothing :do-update-set
:returning])
@ -266,7 +268,7 @@
(reduce (fn [[sql params] [sql' & params']]
[(conj sql sql') (if params' (into params params') params)])
[[] []]
(map #(format-selectable-dsl % {:as (#{:select :from} k)}) xs))]
(map #(format-selectable-dsl % {:as (#{:select :from :window} k)}) xs))]
(into [(str (sql-kw k) " " (str/join ", " sqls))] params))
(let [[sql & params] (format-selectable-dsl xs {:as (#{:select :from} k)})]
(into [(str (sql-kw k) " " sql)] params))))
@ -500,6 +502,8 @@
:where #'format-on-expr
:group-by #'format-group-by
:having #'format-on-expr
:window #'format-selector
:partition-by #'format-selects
:order-by #'format-order-by
:limit #'format-on-expr
:offset #'format-on-expr
@ -664,6 +668,20 @@
(fn [_ [x]]
(let [[sql & params] (format-expr x)]
(into [(str "NOT " sql)] params)))
:over
(fn [_ [& args]]
(let [[sqls params]
(reduce (fn [[sqls params] [e p a]]
(let [[sql-e & params-e] (format-expr e)
[sql-p & params-p] (if (or (nil? p) (map? p))
(format-dsl p {:nested true})
[(format-entity p)])]
[(conj sqls (str sql-e " OVER " sql-p
(when a (str " AS " (format-entity a)))))
(-> params (into params-e) (into params-p))]))
[[] []]
args)]
(into [(str/join ", " sqls)] params)))
:param
(fn [_ [k]]
["?" (->param k)])

View file

@ -2,7 +2,7 @@
(ns honey.sql.helpers
"Helper functions for the built-in clauses in honey.sql."
(:refer-clojure :exclude [update set group-by for])
(:refer-clojure :exclude [update set group-by for partition-by])
(:require [honey.sql :as h]))
(defn- default-merge [current args]
@ -75,6 +75,8 @@
(defn where [& args] (generic :where args))
(defn group-by [& args] (generic :group-by args))
(defn having [& args] (generic :having args))
(defn window [& args] (generic :window args))
(defn partition-by [& args] (generic :partition-by args))
(defn order-by [& args] (generic :order-by args))
(defn limit [& args] (generic-1 :limit args))
(defn offset [& args] (generic-1 :offset args))
@ -88,8 +90,10 @@
;; helpers that produce non-clause expressions -- must be listed below:
(defn composite [& args] (into [:composite] args))
;; to make this easy to use in a select, wrap it so it becomes a function:
(defn over [& args] [(into [:over] args)])
#?(:clj
(assert (= (clojure.core/set (conj @@#'h/base-clause-order
:composite))
:composite :over))
(clojure.core/set (map keyword (keys (ns-publics *ns*)))))))

View file

@ -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])
(:refer-clojure :exclude [update set group-by for partition-by])
(:require #?(:clj [clojure.test :refer [deftest is testing]]
:cljs [cljs.test :refer-macros [deftest is testing]])
[honey.sql :as sql]
@ -9,8 +9,9 @@
:refer [columns cross-join do-update-set from full-join
group-by having insert-into
join left-join limit offset on-conflict order-by
over partition-by
returning right-join
select select-distinct values where with]]))
select select-distinct values where window with]]))
(deftest test-select
(let [m1 (-> (with [:cte (-> (select :*)
@ -305,7 +306,30 @@
" ON CONFLICT (did)"
" DO UPDATE SET dname = EXCLUDED.dname || ? || distributors.dname || ?,"
" downer = EXCLUDED.downer")
23 "Foo Distributors" " (formerly " ")"])))
23 "Foo Distributors" " (formerly " ")"]))
;; insert into / insert into as tests are below
(is (= (-> (select :id
(over [[:avg :salary] (-> (partition-by :department) (order-by :designation)) :Average]
[[:max :salary] :w :MaxSalary]))
(from :employee)
(window :w (partition-by :department))
sql/format)
[(str "SELECT id,"
" AVG(salary) OVER (PARTITION BY department ORDER BY designation ASC) AS Average,"
" MAX(salary) OVER w AS MaxSalary"
" FROM employee"
" WINDOW w AS (PARTITION BY department)")]))
;; test nil / empty window function clause:
(is (= (-> (select :id
(over [[:avg :salary] {} :Average]
[[:max :salary] nil :MaxSalary]))
(from :employee)
sql/format)
[(str "SELECT id,"
" AVG(salary) OVER () AS Average,"
" MAX(salary) OVER () AS MaxSalary"
" FROM employee")]))
)
(deftest issue-293-insert-into-data
;; insert into as (and other tests) based on :insert-into