fix #274 by adding aggregate-by-keys

Signed-off-by: Sean Corfield <sean@corfield.org>
This commit is contained in:
Sean Corfield 2024-03-15 17:54:03 -07:00
parent 10fd00a756
commit 3042079138
No known key found for this signature in database
6 changed files with 98 additions and 5 deletions

View file

@ -4,6 +4,7 @@ Only accretive/fixative changes will be made from now on.
* 1.3.next in progress * 1.3.next in progress
* Address [#275](https://github.com/seancorfield/next-jdbc/issues/275) by noting that PostgreSQL may perform additional SQL queries to produce table names used in qualified result set builders. * Address [#275](https://github.com/seancorfield/next-jdbc/issues/275) by noting that PostgreSQL may perform additional SQL queries to produce table names used in qualified result set builders.
* Address [#274](https://github.com/seancorfield/next-jdbc/issues/274) by adding `next.jdbc.sql/aggregate-by-keys` as a convenient wrapper around `find-by-keys` when you want just a single aggregate value back (such as `count`, `max`, etc).
* Address [#273](https://github.com/seancorfield/next-jdbc/issues/273) by linking to [PG2](https://github.com/igrishaev/pg2) in the PostgreSQL **Tips & Tricks** section. * Address [#273](https://github.com/seancorfield/next-jdbc/issues/273) by linking to [PG2](https://github.com/igrishaev/pg2) in the PostgreSQL **Tips & Tricks** section.
* Address [#268](https://github.com/seancorfield/next-jdbc/issues/268) by expanding the documentation around `insert-multi!` and `insert!`. * Address [#268](https://github.com/seancorfield/next-jdbc/issues/268) by expanding the documentation around `insert-multi!` and `insert!`.
* Update dependency versions (including Clojure). * Update dependency versions (including Clojure).

View file

@ -58,6 +58,10 @@ In the simple case, the `:columns` option expects a vector of keywords and each
> Note: `get-by-id` accepts the same options as `find-by-keys` but it will only ever produce one row, as a hash map, so sort order and pagination are less applicable, although `:columns` may be useful. > Note: `get-by-id` accepts the same options as `find-by-keys` but it will only ever produce one row, as a hash map, so sort order and pagination are less applicable, although `:columns` may be useful.
As of 1.3.next, `aggregate-by-keys` exists as a wrapper around `find-by-keys`
that accepts the same options as `find-by-keys` except that `:columns` may not
be specified (since it is used to add the aggregate to the query).
## Generating Rows and Result Sets ## Generating Rows and Result Sets
Any function that might realize a row or a result set will accept: Any function that might realize a row or a result set will accept:

View file

@ -25,6 +25,12 @@ These functions are described in more detail below. They are deliberately simple
If you prefer to write your SQL separately from your code, take a look at [HugSQL](https://github.com/layerware/hugsql) -- [HugSQL documentation](https://www.hugsql.org/) -- which has a `next.jdbc` adapter, as of version 0.5.1. See below for a "[quick start](#hugsql-quick-start)" for using HugSQL with `next.jdbc`. If you prefer to write your SQL separately from your code, take a look at [HugSQL](https://github.com/layerware/hugsql) -- [HugSQL documentation](https://www.hugsql.org/) -- which has a `next.jdbc` adapter, as of version 0.5.1. See below for a "[quick start](#hugsql-quick-start)" for using HugSQL with `next.jdbc`.
As of 1.3.next, `aggregate-by-keys` exists as a wrapper around `find-by-keys`
that accepts the same options as `find-by-keys` and an aggregate SQL expression
and it returns a single value (the aggregate). `aggregate-by-keys` accepts the
same options as `find-by-keys` except that `:columns` may not be specified
(since it is used to add the aggregate to the query).
## `insert!` ## `insert!`
Given a table name (as a keyword) and a hash map of column names and values, this performs a single row insertion into the database: Given a table name (as a keyword) and a hash map of column names and values, this performs a single row insertion into the database:
@ -247,6 +253,26 @@ If you want to match all rows in a table -- perhaps with the pagination options
If no rows match, `find-by-keys` returns `[]`, just like `execute!`. If no rows match, `find-by-keys` returns `[]`, just like `execute!`.
## `aggregate-by-keys`
Added in 1.3.next, this is a wrapper around `find-by-keys` that makes it easier
to perform aggregate queries::
```clojure
(sql/aggregate-by-keys ds :address "count(*)" {:name "Stella"
:email "stella@artois.beer"})
;; is roughly equivalent to
(-> (sql/find-by-keys ds :address {:name "Stella" :email "stella@artois.beer"}
{:columns [["count(*)" :next_jdbc_aggregate_123]]})
(first)
(get :next_jdbc_aggregate_123))
```
(where `:next_jdbc_aggregate_123` is a unique alias generated by `next.jdbc`,
derived from the aggregate expression string).
> Note: the SQL string provided for the aggregate is copied exactly as-is into the generated SQL -- you are responsible for ensuring it is legal SQL!
## `get-by-id` ## `get-by-id`
Given a table name (as a keyword) and a primary key value, with an optional primary key column name, execute a query on the database: Given a table name (as a keyword) and a primary key value, with an optional primary key column name, execute a query on the database:

View file

@ -232,6 +232,15 @@
:all #{:all}) :all #{:all})
:opts (s/? ::opts-map))) :opts (s/? ::opts-map)))
(s/fdef sql/aggregate-by-keys
:args (s/cat :connectable ::connectable
:table keyword?
:aggregate string?
:key-map (s/or :example ::example-map
:where ::sql-params
:all #{:all})
:opts (s/? ::opts-map)))
(s/fdef sql/get-by-id (s/fdef sql/get-by-id
:args (s/alt :with-id (s/cat :connectable ::connectable :args (s/alt :with-id (s/cat :connectable ::connectable
:table keyword? :table keyword?

View file

@ -1,4 +1,4 @@
;; copyright (c) 2019-2023 Sean Corfield, all rights reserved ;; copyright (c) 2019-2024 Sean Corfield, all rights reserved
(ns next.jdbc.sql (ns next.jdbc.sql
"Some utility functions that make common operations easier by "Some utility functions that make common operations easier by
@ -21,10 +21,11 @@
In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY` In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY`
clause to the generated SQL." clause to the generated SQL."
(:require [next.jdbc :refer [execute! execute-one! execute-batch!]] (:require [clojure.string :as str]
[next.jdbc :refer [execute! execute-batch! execute-one!]]
[next.jdbc.sql.builder [next.jdbc.sql.builder
:refer [for-delete for-insert for-insert-multi :refer [for-delete for-insert for-insert-multi for-query
for-query for-update]])) for-update]]))
(set! *warn-on-reflection* true) (set! *warn-on-reflection* true)
@ -138,6 +139,42 @@
(let [opts (merge (:options connectable) opts)] (let [opts (merge (:options connectable) opts)]
(execute! connectable (for-query table key-map opts) opts)))) (execute! connectable (for-query table key-map opts) opts))))
(defn aggregate-by-keys
"A wrapper over `find-by-keys` that additionally takes an aggregate SQL
expression (a string), and returns just a single result: the value of that
of that aggregate for the matching rows.
Accepts all the same options as `find-by-keys` except `:columns` since that
is used internally by this wrapper to pass the aggregate expression in."
([connectable table aggregate key-map]
(aggregate-by-keys connectable table aggregate key-map {}))
([connectable table aggregate key-map opts]
(let [opts (merge (:options connectable) opts)
_
(when-not (string? aggregate)
(throw (IllegalArgumentException.
"aggregate-by-keys requires a string aggregate expression")))
_
(when (:columns opts)
(throw (IllegalArgumentException.
"aggregate-by-keys does not support the :columns option")))
;; this should be unique enough as an alias to never clash with
;; a real column name in anyone's tables -- in addition it is
;; stable for a given aggregate expression so it should allow
;; for query caching in the JDBC driver:
;; (we use abs to avoid negative hash codes which would produce
;; a hyphen in the alias name which is not valid in SQL identifiers)
total-name (str "next_jdbc_aggregate_"
(Math/abs (.hashCode ^String aggregate)))
total-column (keyword total-name)
;; because some databases return uppercase column names:
total-col-u (keyword (str/upper-case total-name))]
(-> (find-by-keys connectable table key-map
(assoc opts :columns [[aggregate total-column]]))
(first)
(as-> row (or (get row total-column) (get row total-col-u)))))))
(defn get-by-id (defn get-by-id
"Syntactic sugar over `execute-one!` to make certain common queries easier. "Syntactic sugar over `execute-one!` to make certain common queries easier.

View file

@ -1,4 +1,4 @@
;; copyright (c) 2019-2023 Sean Corfield, all rights reserved ;; copyright (c) 2019-2024 Sean Corfield, all rights reserved
(ns next.jdbc.sql-test (ns next.jdbc.sql-test
"Tests for the syntactic sugar SQL functions." "Tests for the syntactic sugar SQL functions."
@ -58,6 +58,22 @@
(is (every? meta rs)) (is (every? meta rs))
(is (= 2 ((column :FRUIT/ID) (first rs))))))) (is (= 2 ((column :FRUIT/ID) (first rs)))))))
(deftest test-aggregate-by-keys
(let [ds-opts (jdbc/with-options (ds) (default-options))]
(let [count-v (sql/aggregate-by-keys ds-opts :fruit "count(*)" {:appearance "neon-green"})]
(is (number? count-v))
(is (= 0 count-v)))
(let [count-v (sql/aggregate-by-keys ds-opts :fruit "count(*)" {:appearance "yellow"})]
(is (= 1 count-v)))
(let [count-v (sql/aggregate-by-keys ds-opts :fruit "count(*)" :all)]
(is (= 4 count-v)))
(let [max-id (sql/aggregate-by-keys ds-opts :fruit "max(id)" :all)]
(is (= 4 max-id)))
(let [min-name (sql/aggregate-by-keys ds-opts :fruit "min(name)" :all)]
(is (= "Apple" min-name)))
(is (thrown? IllegalArgumentException
(sql/aggregate-by-keys ds-opts :fruit "count(*)" :all {:columns []})))))
(deftest test-get-by-id (deftest test-get-by-id
(let [ds-opts (jdbc/with-options (ds) (default-options))] (let [ds-opts (jdbc/with-options (ds) (default-options))]
(is (nil? (sql/get-by-id ds-opts :fruit -1))) (is (nil? (sql/get-by-id ds-opts :fruit -1)))