Fixes #139 by adding select! and select-one!
This commit is contained in:
parent
82a6242419
commit
fdeea5c0e9
6 changed files with 222 additions and 3 deletions
|
|
@ -3,7 +3,8 @@
|
||||||
Only accretive/fixative changes will be made from now on.
|
Only accretive/fixative changes will be made from now on.
|
||||||
|
|
||||||
Changes made on **develop** since the 1.1.582 release:
|
Changes made on **develop** since the 1.1.582 release:
|
||||||
* If `ResultSet.getMetaData()` returns `null`, we assume the column count is zero, i.e., an empty result set.
|
* Fix #139 by adding `next.jdbc.plan/select-one!` and `next.jdbc.plan/select!`.
|
||||||
|
* If `ResultSet.getMetaData()` returns `null`, we assume the column count is zero, i.e., an empty result set. This should "never happen" but some JDBC drivers are badly behaved and their idea of an "empty result set" does not match the JDBC API spec.
|
||||||
|
|
||||||
## Stable Builds
|
## Stable Builds
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -101,4 +101,10 @@ The `transact` function and `with-transaction` macro accept the following option
|
||||||
* `:read-only` -- a `Boolean` that indicates whether the transaction should be read-only or not (the default),
|
* `:read-only` -- a `Boolean` that indicates whether the transaction should be read-only or not (the default),
|
||||||
* `:rollback-only` -- a `Boolean` that indicates whether the transaction should commit on success (the default) or rollback.
|
* `:rollback-only` -- a `Boolean` that indicates whether the transaction should commit on success (the default) or rollback.
|
||||||
|
|
||||||
|
## Plan Selection
|
||||||
|
|
||||||
|
The `next.jdbc.plan/select!` function accepts the following specific option:
|
||||||
|
|
||||||
|
* `:into` -- a data structure into which the selected result from a `plan` operation are poured; by default this is `[]`; could be any value that is acceptable as the first argument to `into`, subject to `into` accepting the sequence of values produced by the `plan` reduction.
|
||||||
|
|
||||||
[<: Transactions](/doc/transactions.md) | [`datafy`, `nav`, and `:schema` :>](/doc/datafy-nav-and-schema.md)
|
[<: Transactions](/doc/transactions.md) | [`datafy`, `nav`, and `:schema` :>](/doc/datafy-nav-and-schema.md)
|
||||||
|
|
|
||||||
|
|
@ -230,7 +230,7 @@ Any operation that can perform key-based lookup can be used here without creatin
|
||||||
|
|
||||||
This means that `select-keys` can be used to create regular Clojure hash map from (a subset of) columns in the row, without realizing the row, and it will not implement `Datafiable` or `Navigable`.
|
This means that `select-keys` can be used to create regular Clojure hash map from (a subset of) columns in the row, without realizing the row, and it will not implement `Datafiable` or `Navigable`.
|
||||||
|
|
||||||
If you wish to create a Clojure hash map that supports that lazy navigation, you can call `next.jdbc.result-set/datafiable-row`, passing in the current row, a `connectable`, and an options hash map, just as you passed into `plan`. Compare the difference in output between these four expressions:
|
If you wish to create a Clojure hash map that supports that lazy navigation, you can call `next.jdbc.result-set/datafiable-row`, passing in the current row, a `connectable`, and an options hash map, just as you passed into `plan`. Compare the difference in output between these four expressions (see below for a simpler way to do this):
|
||||||
|
|
||||||
```clojure
|
```clojure
|
||||||
;; selects specific keys (as simple keywords):
|
;; selects specific keys (as simple keywords):
|
||||||
|
|
@ -275,6 +275,93 @@ The order of the column names returned by `column-names` matches SQL's natural o
|
||||||
|
|
||||||
> Note: since `plan` expects you to process the result set via reduction, you should not use it for DDL or for SQL statements that only produce update counts.
|
> Note: since `plan` expects you to process the result set via reduction, you should not use it for DDL or for SQL statements that only produce update counts.
|
||||||
|
|
||||||
|
As of 1.1.next, two helper functions are available to make some `plan` operations easier:
|
||||||
|
|
||||||
|
* `next.jdbc.plan/select-one!` -- reduces over `plan` and returns part of just the first row,
|
||||||
|
* `next.jdbc.plan/select!` -- reduces over `plan` and returns a sequence of parts of each row.
|
||||||
|
|
||||||
|
`select!` accepts a vector of column names to extract or a function to apply to each row. It is equivalent to the following:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
;; select! with vector of column names:
|
||||||
|
user=> (into [] (map #(select-keys % cols)) (jdbc/plan ...))
|
||||||
|
;; select! with a function:
|
||||||
|
user=> (into [] (map f) (jdbc/plan ...))
|
||||||
|
```
|
||||||
|
|
||||||
|
The `:into` option lets you override the default of `[]` as the first argument to `into`.
|
||||||
|
|
||||||
|
`select-one!` performs the same transformation on just the first row returned from a reduction over `plan`, equivalent to the following:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
;; select-one! with vector of column names:
|
||||||
|
user=> (reduce (fn [_ row] (reduced (select-keys row cols))) nil (jdbc/plan ...))
|
||||||
|
;; select-one! with a function:
|
||||||
|
user=> (reduce (fn [_ row] (reduced (f row))) nil (jdbc/plan ...))
|
||||||
|
```
|
||||||
|
|
||||||
|
For example:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
;; select columns:
|
||||||
|
user=> (plan/select-one!
|
||||||
|
ds [:n] ["select count(*) as n from invoice where customer_id = ?" 100])
|
||||||
|
{:n 3}
|
||||||
|
;; apply a function:
|
||||||
|
user=> (plan/select-one!
|
||||||
|
ds :n ["select count(*) as n from invoice where customer_id = ?" 100])
|
||||||
|
3
|
||||||
|
```
|
||||||
|
|
||||||
|
Here are some of the above sequence-producing operations, showing their `select!` equivalent:
|
||||||
|
|
||||||
|
```clojure
|
||||||
|
user=> (require '[next.jdbc.plan :as plan])
|
||||||
|
nil
|
||||||
|
user=> (into #{}
|
||||||
|
(map :product)
|
||||||
|
(jdbc/plan ds ["select * from invoice where customer_id = ?" 100]))
|
||||||
|
#{"apple" "banana" "cucumber"}
|
||||||
|
;; or:
|
||||||
|
user=> (plan/select! ds
|
||||||
|
:product
|
||||||
|
["select * from invoice where customer_id = ?" 100]
|
||||||
|
{:into #{}}) ; product a set, rather than a vector
|
||||||
|
#{"apple" "banana" "cucumber"}
|
||||||
|
;; selects specific keys (as simple keywords):
|
||||||
|
user=> (into []
|
||||||
|
(map #(select-keys % [:id :product :unit_price :unit_cost :customer_id]))
|
||||||
|
(jdbc/plan ds ["select * from invoice where customer_id = ?" 100]))
|
||||||
|
;; or:
|
||||||
|
user=> (plan/select! ds
|
||||||
|
[:id :product :unit_price :unit_cost :customer_id]
|
||||||
|
["select * from invoice where customer_id = ?" 100])
|
||||||
|
;; selects specific keys (as qualified keywords):
|
||||||
|
user=> (into []
|
||||||
|
(map #(select-keys % [:invoice/id :invoice/product
|
||||||
|
:invoice/unit_price :invoice/unit_cost
|
||||||
|
:invoice/customer_id]))
|
||||||
|
(jdbc/plan ds ["select * from invoice where customer_id = ?" 100]))
|
||||||
|
;; or:
|
||||||
|
user=> (plan/select! ds
|
||||||
|
[:invoice/id :invoice/product
|
||||||
|
:invoice/unit_price :invoice/unit_cost
|
||||||
|
:invoice/customer_id]
|
||||||
|
["select * from invoice where customer_id = ?" 100])
|
||||||
|
;; selects specific keys (as qualified keywords -- ignoring the table name):
|
||||||
|
user=> (into []
|
||||||
|
(map #(select-keys % [:foo/id :bar/product
|
||||||
|
:quux/unit_price :wibble/unit_cost
|
||||||
|
:blah/customer_id]))
|
||||||
|
(jdbc/plan ds ["select * from invoice where customer_id = ?" 100]))
|
||||||
|
;; or:
|
||||||
|
user=> (plan/select! ds
|
||||||
|
[:foo/id :bar/product
|
||||||
|
:quux/unit_price :wibble/unit_cost
|
||||||
|
:blah/customer_id]
|
||||||
|
["select * from invoice where customer_id = ?" 100])
|
||||||
|
```
|
||||||
|
|
||||||
## Datasources, Connections & Transactions
|
## Datasources, Connections & Transactions
|
||||||
|
|
||||||
In the examples above, we created a datasource and then passed it into each function call. When `next.jdbc` is given a datasource, it creates a `java.sql.Connection` from it, uses it for the SQL operation (by creating and populating a `java.sql.PreparedStatement` from the connection and the SQL string and parameters passed in), and then closes it. If you're not using a connection pooling datasource (see below), that can be quite an overhead: setting up database connections to remote servers is not cheap!
|
In the examples above, we created a datasource and then passed it into each function call. When `next.jdbc` is given a datasource, it creates a `java.sql.Connection` from it, uses it for the SQL operation (by creating and populating a `java.sql.PreparedStatement` from the connection and the SQL string and parameters passed in), and then closes it. If you're not using a connection pooling datasource (see below), that can be quite an overhead: setting up database connections to remote servers is not cheap!
|
||||||
|
|
|
||||||
68
src/next/jdbc/plan.clj
Normal file
68
src/next/jdbc/plan.clj
Normal file
|
|
@ -0,0 +1,68 @@
|
||||||
|
;; copyright (c) 2020 Sean Corfield, all rights reserved
|
||||||
|
|
||||||
|
(ns next.jdbc.plan
|
||||||
|
"Some helper functions that make common operations with `next.jdbc/plan`
|
||||||
|
much easier."
|
||||||
|
(:require [next.jdbc :as jdbc]))
|
||||||
|
|
||||||
|
(defn select-one!
|
||||||
|
"Execute the SQL and params using `next.jdbc/plan` and return just the
|
||||||
|
selected columns from just the first row.
|
||||||
|
|
||||||
|
`(plan/select-one! ds [:total] [\"select count(*) as total from table\"])`
|
||||||
|
;;=> {:total 42}
|
||||||
|
|
||||||
|
If the `cols` argument is a vector of columns to select, then it is
|
||||||
|
applied using `select-keys`, otherwise, the `cols` argument is used as
|
||||||
|
a function directly. That means it can be a simple keyword to return
|
||||||
|
just that column -- which is the most common expected usage:
|
||||||
|
|
||||||
|
`(plan/select-one! ds :total [\"select count(*) as total from table\"])`
|
||||||
|
;;=> 42
|
||||||
|
|
||||||
|
The usual caveats apply about operations on a raw result set that
|
||||||
|
can be done without realizing the whole row."
|
||||||
|
([connectable cols sql-params]
|
||||||
|
(select-one! connectable cols sql-params {}))
|
||||||
|
([connectable cols sql-params opts]
|
||||||
|
(reduce (fn [_ row] (reduced (if (vector? cols)
|
||||||
|
(select-keys row cols)
|
||||||
|
(cols row))))
|
||||||
|
nil
|
||||||
|
(jdbc/plan connectable sql-params opts))))
|
||||||
|
|
||||||
|
(defn select!
|
||||||
|
"Execute the SQL and params using `next.jdbc/plan` and (by default)
|
||||||
|
return a vector of rows with just the selected columns.
|
||||||
|
|
||||||
|
`(plan/select! ds [:id :name] [\"select * from table\"])`
|
||||||
|
|
||||||
|
If the `cols` argument is a vector of columns to select, then it is
|
||||||
|
applied as:
|
||||||
|
|
||||||
|
`(into [] (map #(select-keys % cols)) (jdbc/plan ...))`
|
||||||
|
|
||||||
|
Otherwise, the `cols` argument is used as a function and mapped over
|
||||||
|
the raw result set as:
|
||||||
|
|
||||||
|
`(into [] (map cols) (jdbc/plan ...))`
|
||||||
|
|
||||||
|
The usual caveats apply about operations on a raw result set that
|
||||||
|
can be done without realizing the whole row.
|
||||||
|
|
||||||
|
Note: this allows for the following usage, which returns a vector
|
||||||
|
of all the values for a single column:
|
||||||
|
|
||||||
|
`(plan/select! ds :id (jdbc/plan ...))`
|
||||||
|
|
||||||
|
The result is a vector by default, but can be changed using the
|
||||||
|
`:into` option to provide the initial data structure into which
|
||||||
|
the selected columns are poured, e.g., `:into #{}`"
|
||||||
|
([connectable cols sql-params]
|
||||||
|
(select! connectable cols sql-params {}))
|
||||||
|
([connectable cols sql-params opts]
|
||||||
|
(into (or (:into opts) [])
|
||||||
|
(map (if (vector? cols)
|
||||||
|
#(select-keys % cols)
|
||||||
|
cols))
|
||||||
|
(jdbc/plan connectable sql-params opts))))
|
||||||
57
test/next/jdbc/plan_test.clj
Normal file
57
test/next/jdbc/plan_test.clj
Normal file
|
|
@ -0,0 +1,57 @@
|
||||||
|
;; copyright (c) 2020 Sean Corfield, all rights reserved
|
||||||
|
|
||||||
|
(ns next.jdbc.plan-test
|
||||||
|
"Tests for the plan helpers."
|
||||||
|
(:require [clojure.test :refer [deftest is use-fixtures]]
|
||||||
|
[next.jdbc.plan :as plan]
|
||||||
|
[next.jdbc.specs :as specs]
|
||||||
|
[next.jdbc.test-fixtures
|
||||||
|
:refer [with-test-db ds]]))
|
||||||
|
|
||||||
|
(set! *warn-on-reflection* true)
|
||||||
|
|
||||||
|
;; around each test because of the folding tests using 1,000 rows
|
||||||
|
(use-fixtures :each with-test-db)
|
||||||
|
|
||||||
|
(specs/instrument)
|
||||||
|
|
||||||
|
(deftest select-one!-tests
|
||||||
|
(is (= {:id 1}
|
||||||
|
(plan/select-one! (ds) [:id] ["select * from fruit order by id"])))
|
||||||
|
(is (= 1
|
||||||
|
(plan/select-one! (ds) :id ["select * from fruit order by id"])))
|
||||||
|
(is (= "Banana"
|
||||||
|
(plan/select-one! (ds) :name ["select * from fruit where id = ?" 2])))
|
||||||
|
(is (= [1 "Apple"]
|
||||||
|
(plan/select-one! (ds) (juxt :id :name)
|
||||||
|
["select * from fruit order by id"])))
|
||||||
|
(is (= {:id 1 :name "Apple"}
|
||||||
|
(plan/select-one! (ds) #(select-keys % [:id :name])
|
||||||
|
["select * from fruit order by id"]))))
|
||||||
|
|
||||||
|
(deftest select-vector-tests
|
||||||
|
(is (= [{:id 1} {:id 2} {:id 3} {:id 4}]
|
||||||
|
(plan/select! (ds) [:id] ["select * from fruit order by id"])))
|
||||||
|
(is (= [1 2 3 4]
|
||||||
|
(plan/select! (ds) :id ["select * from fruit order by id"])))
|
||||||
|
(is (= ["Banana"]
|
||||||
|
(plan/select! (ds) :name ["select * from fruit where id = ?" 2])))
|
||||||
|
(is (= [[2 "Banana"]]
|
||||||
|
(plan/select! (ds) (juxt :id :name)
|
||||||
|
["select * from fruit where id = ?" 2])))
|
||||||
|
(is (= [{:id 2 :name "Banana"}]
|
||||||
|
(plan/select! (ds) [:id :name]
|
||||||
|
["select * from fruit where id = ?" 2]))))
|
||||||
|
|
||||||
|
(deftest select-set-tests
|
||||||
|
(is (= #{{:id 1} {:id 2} {:id 3} {:id 4}}
|
||||||
|
(plan/select! (ds) [:id] ["select * from fruit order by id"]
|
||||||
|
{:into #{}})))
|
||||||
|
(is (= #{1 2 3 4}
|
||||||
|
(plan/select! (ds) :id ["select * from fruit order by id"]
|
||||||
|
{:into #{}}))))
|
||||||
|
|
||||||
|
(deftest select-map-tests
|
||||||
|
(is (= {1 "Apple", 2 "Banana", 3 "Peach", 4 "Orange"}
|
||||||
|
(plan/select! (ds) (juxt :id :name) ["select * from fruit order by id"]
|
||||||
|
{:into {}}))))
|
||||||
|
|
@ -15,7 +15,7 @@
|
||||||
[next.jdbc.result-set :as rs]
|
[next.jdbc.result-set :as rs]
|
||||||
[next.jdbc.specs :as specs]
|
[next.jdbc.specs :as specs]
|
||||||
[next.jdbc.types :as types])
|
[next.jdbc.types :as types])
|
||||||
(:import (java.sql ResultSet ResultSetMetaData Types)))
|
(:import (java.sql ResultSet ResultSetMetaData)))
|
||||||
|
|
||||||
(set! *warn-on-reflection* true)
|
(set! *warn-on-reflection* true)
|
||||||
|
|
||||||
|
|
|
||||||
Loading…
Reference in a new issue