Skip to content

Commit c97193d

Browse files
scimetfookitallis
andauthored
Support WITHIN GROUP for aggregate expressions (#47)
Co-authored-by: Akshay Gupta <kitallis@gmail.com>
1 parent e96970c commit c97193d

File tree

4 files changed

+99
-14
lines changed

4 files changed

+99
-14
lines changed

README.md

Lines changed: 25 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -24,19 +24,22 @@ The query creation and usage is exactly the same as honeysql.
2424
- [pattern matching](#pattern-matching)
2525
- [except](#except)
2626
- [filter](#filter)
27+
- [within group](#within-group)
2728
- [SQL functions](#sql-functions)
2829
- [License](#license)
2930

3031
## Usage
3132

3233
### REPL
34+
3335
```clojure
3436
(require '[honeysql.core :as sql]
3537
'[honeysql.helpers :refer :all :as sqlh]
3638
'[honeysql-postgres.helpers :as psqlh])
3739
```
3840

3941
### distinct-on
42+
4043
`select` can be written with a `distinct on` clause
4144
``` clojure
4245
(-> (select :column-1 :column-2 :column-3)
@@ -47,6 +50,7 @@ The query creation and usage is exactly the same as honeysql.
4750
```
4851

4952
### upsert
53+
5054
`upsert` can be written either way. You can make use of `do-update-set!` over `do-update-set`, if you want to modify the some column values in case of conflicts.
5155
```clojure
5256
(-> (insert-into :distributors)
@@ -69,6 +73,7 @@ The query creation and usage is exactly the same as honeysql.
6973
```
7074

7175
### insert into with alias
76+
7277
`insert-into-as` can be used to write insert statements with table name aliased.
7378
```clojure
7479
(-> (psqlh/insert-into-as :distributors :d)
@@ -84,6 +89,7 @@ The query creation and usage is exactly the same as honeysql.
8489
```
8590

8691
### over
92+
8793
You can make use of `over` to write window functions where it takes in vectors with aggregator functions and window functions along with optional alias like `(over [aggregator-function window-function alias])`, the can be coupled with the `window` clause to write window-function functions with alias that is later defines the window-function, like `(-> (over [aggregator-function :w]) (window :w window-function))`.
8894
```clojure
8995
(-> (select :id)
@@ -108,6 +114,7 @@ You can make use of `over` to write window functions where it takes in vectors w
108114
```
109115

110116
### create table
117+
111118
`create-table` and `with-columns` can be used to create tables along with the SQL functions, where `create-table` takes a table name as argument and `with-columns` takes a vector of vectors as argument, where the vectors describe the column properties as `[:column-name :datatype :constraints ... ]`.
112119
```clojure
113120
(-> (psqlh/create-table :films)
@@ -122,13 +129,15 @@ You can make use of `over` to write window functions where it takes in vectors w
122129
```
123130

124131
### drop table
132+
125133
`drop-table` is used to drop tables
126134
```clojure
127135
(sql/format (psqlh/drop-table :cities :towns :vilages))
128136
=> ["DROP TABLE cities, towns, vilages"]
129137
```
130138

131139
### alter table
140+
132141
use `alter-table` along with `add-column` & `drop-column` to modify table level details
133142
```clojure
134143
(-> (psqlh/alter-table :employees)
@@ -143,6 +152,7 @@ use `alter-table` along with `add-column` & `drop-column` to modify table level
143152
```
144153

145154
### create-extension
155+
146156
`create-extension` can be used to create extensions with a given keyword.
147157
```clojure
148158
(-> (psqlh/create-extension :uuid-ossp :if-not-exists? true)
@@ -161,6 +171,7 @@ use `alter-table` along with `add-column` & `drop-column` to modify table level
161171
```
162172

163173
### pattern matching
174+
164175
The `ilike` and `not-ilike` operators can be used to query data using a pattern matching technique.
165176
- like
166177
```clojure
@@ -180,6 +191,7 @@ The `ilike` and `not-ilike` operators can be used to query data using a pattern
180191
```
181192

182193
### except
194+
183195
```clojure
184196
(sql/format
185197
{:except
@@ -200,7 +212,19 @@ The `ilike` and `not-ilike` operators can be used to query data using a pattern
200212
=> ["SELECT count(*) , count(*) FILTER (WHERE i < ?) AS foo, count(*) FILTER (WHERE i BETWEEN ? AND ?) AS bar FROM generate_series(1,10) AS s(i)" 5 3 10]
201213
```
202214

215+
### within group
216+
217+
``` clojure
218+
(-> (select (sql/call :count :*))
219+
(within-group [(sql/call :percentile_disc (hsql-types/array [0.25 0.5 0.75])) (order-by :s.i) :alias])
220+
(from (sql/raw "generate_series(1,10) AS s(i)"))
221+
(sql/format))
222+
=> ["SELECT count(*) , percentile_disc(ARRAY[?, ?, ?]) WITHIN GROUP (ORDER BY s.i) AS alias FROM generate_series(1,10) AS s(i)"
223+
0.25 0.50 0.75]
224+
```
225+
203226
### SQL functions
227+
204228
The following are the SQL functions added in `honeysql-postgres`
205229
- not
206230
```clojure
@@ -257,7 +281,7 @@ The following are the SQL functions added in `honeysql-postgres`
257281
=> ["CHECK(a = b)"]
258282

259283
(sql/format (sql/call :check [:= :a :b] [:= :c :d]))
260-
["CHECK(a = b AND c = d)"]
284+
=> ["CHECK(a = b AND c = d)"]
261285
```
262286

263287
## License

src/honeysql_postgres/format.cljc

Lines changed: 15 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,8 @@
1313
:add-column 30
1414
:drop-column 40
1515
:create-view 40
16-
:filter 54
16+
:filter 55
17+
:within-group 55
1718
:over 55
1819
:insert-into-as 60
1920
:partition-by 165
@@ -236,6 +237,19 @@
236237
(binding [sqlf/*subquery?* false]
237238
(string/join " EXCEPT ALL " (map sqlf/to-sql maps))))
238239

240+
(defmethod format-clause :within-group [[_ expr] m]
241+
(let [format (fn [expr]
242+
(let [[expression clause alias] (map sqlf/to-sql expr)]
243+
(->> alias
244+
(str " AS ")
245+
(when alias)
246+
(str expression " WITHIN GROUP " clause))))]
247+
(-> m
248+
:select
249+
seq
250+
(when ", ")
251+
(str (sqlf/comma-join (map format expr))))))
252+
239253
(override-default-clause-priority)
240254

241255
(defmethod format-modifiers :distinct-on [[_ & fields]]

src/honeysql_postgres/helpers.cljc

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -72,6 +72,9 @@
7272
(defhelper insert-into-as [m fields]
7373
(assoc m :insert-into-as (sqlh/collify fields)))
7474

75+
(defhelper within-group [m args]
76+
(assoc m :within-group (sqlh/collify args)))
77+
7578
(defhelper create-extension [m extension-name]
7679
(assoc m :create-extension (sqlh/collify extension-name)))
7780

test/honeysql_postgres/postgres_test.cljc

Lines changed: 56 additions & 12 deletions
Original file line numberDiff line numberDiff line change
@@ -1,18 +1,52 @@
11
(ns honeysql-postgres.postgres-test
22
(:refer-clojure :exclude [update partition-by filter])
3-
(:require [honeysql-postgres.helpers :as sqlph :refer [upsert on-conflict do-nothing on-conflict-constraint
4-
returning do-update-set do-update-set!
5-
alter-table rename-column drop-column
6-
add-column partition-by insert-into-as
7-
create-table rename-table drop-table
8-
window create-view over with-columns
9-
create-extension drop-extension filter]]
10-
[honeysql.helpers :as sqlh :refer [insert-into values where select columns
11-
from order-by update sset query-values
12-
modifiers]]
13-
[honeysql.core :as sql]
3+
(:require [clojure.string :as str]
144
[clojure.test :as test :refer [deftest is testing]]
15-
[clojure.string :as str]))
5+
[honeysql-postgres.helpers
6+
:as
7+
sqlph
8+
:refer
9+
[add-column
10+
alter-table
11+
create-extension
12+
create-table
13+
create-view
14+
do-nothing
15+
do-update-set
16+
do-update-set!
17+
drop-column
18+
drop-extension
19+
drop-table
20+
filter
21+
insert-into-as
22+
on-conflict
23+
on-conflict-constraint
24+
over
25+
partition-by
26+
rename-column
27+
rename-table
28+
returning
29+
upsert
30+
window
31+
with-columns
32+
within-group]]
33+
[honeysql.core :as sql]
34+
[honeysql.helpers
35+
:as
36+
sqlh
37+
:refer
38+
[columns
39+
from
40+
insert-into
41+
modifiers
42+
order-by
43+
query-values
44+
select
45+
sset
46+
update
47+
values
48+
where]]
49+
[honeysql.types :as hsql-types]))
1650

1751
(deftest upsert-test
1852
(testing "upsert sql generation for postgresql"
@@ -272,6 +306,16 @@
272306
(modifiers :distinct-on :a :b)
273307
(sql/format :quoting :ansi))))))
274308

309+
(deftest within-group-test
310+
(is (= ["rank() WITHIN GROUP (ORDER BY i)"]
311+
(sql/format (within-group [(sql/call :rank) (order-by :i)]))))
312+
313+
(is (= ["SELECT count(*) , percentile_disc(ARRAY[?, ?, ?]) WITHIN GROUP (ORDER BY s.i) AS alias FROM generate_series(1,10) AS s(i)"
314+
0.25 0.50 0.75]
315+
(-> (select (sql/call :count :*))
316+
(within-group [(sql/call :percentile_disc (hsql-types/array [0.25 0.5 0.75])) (order-by :s.i) :alias])
317+
(from (sql/raw "generate_series(1,10) AS s(i)"))
318+
(sql/format)))))
275319
(deftest create-extension-test
276320
(testing "create extension"
277321
(is (= ["CREATE EXTENSION \"uuid-ossp\""]

0 commit comments

Comments
 (0)