diff --git a/doc/differences.md b/doc/differences.md index cb1ba8a..33ad0d5 100644 --- a/doc/differences.md +++ b/doc/differences.md @@ -54,5 +54,4 @@ These are mostly drawn from Issue #5 although most of the bullets in that issue * Keyword options no longer end in `?` -- to reflect the latest best practice on predicates vs. attributes, * `with-db-connection` has been replaced by just `with-open` containing a call to `get-connection`, * `with-transaction` can take a `:rollback-only` option, but there is no way to change a transaction to rollback _dynamically_; throw an exception instead (all transactions roll back on an exception) -* `find-by-keys` no longer supports `:order-by` (but this may come back), * The extension points for setting parameters and reading columns are now `SettableParameter` and `ReadableColumn` protocols. diff --git a/doc/friendly_sql_fns.md b/doc/friendly_sql_fns.md index 81877b9..35c7427 100644 --- a/doc/friendly_sql_fns.md +++ b/doc/friendly_sql_fns.md @@ -101,6 +101,17 @@ Given a table name (as a keyword) and either a hash map of column names and valu "Stella" "stella@artois.beer"]) ``` +`find-by-keys` supports an `:order-by` option which can specify a vector of column names to sort the results by. Elements may be column names or pairs of a column name and the direction to sort: `:asc` or `:desc`: + +```clojure +(sql/find-by-keys ds :address + {:name "Stella" :email "stella@artois.beer"} + {:order-by [[:id :desc]]}) +;; equivalent to +(jdbc/execute! ds ["SELECT * FROM address WHERE name = ? AND email = ? ORDER BY id DESC" + "Stella" "stella@artois.beer"]) +``` + ## `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: diff --git a/doc/getting_started.md b/doc/getting_started.md index 12d2d8f..32dc195 100644 --- a/doc/getting_started.md +++ b/doc/getting_started.md @@ -9,12 +9,12 @@ It is designed to work with Clojure 1.10 or later, supports `datafy`/`nav`, and You can add `next.jdbc` to your project with either: ```clojure -{next.jdbc {:mvn/version "1.0.0-alpha4"}} +{next.jdbc {:mvn/version "1.0.0-alpha5"}} ``` for `deps.edn` or: ```clojure -[next.jdbc "1.0.0-alpha4"] +[next.jdbc "1.0.0-alpha5"] ``` for `project.clj` or `build.boot`. @@ -29,7 +29,7 @@ For the examples in this documentation, we will use a local H2 database on disk, ```clojure ;; deps.edn {:deps {org.clojure/clojure {:mvn/version "1.10.0"} - next.jdbc {:mvn/version "1.0.0-alpha4"} + next.jdbc {:mvn/version "1.0.0-alpha5"} com.h2database/h2 {:mvn/version "1.4.197"}}} ``` diff --git a/pom.xml b/pom.xml index eead8fd..7b1c2c9 100644 --- a/pom.xml +++ b/pom.xml @@ -3,7 +3,7 @@ 4.0.0 seancorfield next.jdbc - 1.0.0-alpha4 + 1.0.0-alpha5 next.jdbc The next generation of clojure.java.jdbc: a new low-level Clojure wrapper for JDBC-based access to databases. diff --git a/src/next/jdbc/sql.clj b/src/next/jdbc/sql.clj index 5ad3294..ebe06af 100644 --- a/src/next/jdbc/sql.clj +++ b/src/next/jdbc/sql.clj @@ -4,25 +4,29 @@ "Some utility functions that make common operations easier by providing some syntactic sugar over `execute!`/`execute-one!`. - This is intended to provide a minimal level of parity with clojure.java.jdbc - (insert!, update!, delete!, etc). For anything more complex, use a library - like HoneySQL https://github.com/jkk/honeysql to generate SQL + parameters. + This is intended to provide a minimal level of parity with + `clojure.java.jdbc` (`insert!`, `update!`, `delete!`, etc). + For anything more complex, use a library like HoneySQL + https://github.com/jkk/honeysql to generate SQL + parameters. The following options are supported: - * :table-fn -- specify a function used to convert table names (strings) - to SQL entity names -- see the next.jdbc.quoted namespace for the + * `:table-fn` -- specify a function used to convert table names (strings) + to SQL entity names -- see the `next.jdbc.quoted` namespace for the most common quoting strategy functions, - * :column-fn -- specify a function used to convert column names (strings) - to SQL entity names -- see the next.jdbc.quoted namespace for the - most common quoting strategy functions." + * `:column-fn` -- specify a function used to convert column names (strings) + to SQL entity names -- see the `next.jdbc.quoted` namespace for the + most common quoting strategy functions. + + In addition, `find-by-keys` supports `:order-by` to add an `ORDER BY` + clause to the generated SQL." (:require [clojure.string :as str] [next.jdbc :refer [execute! execute-one!]])) (defn- by-keys - "Given a hash map of column names and values and a clause type (:set, :where), - return a vector of a SQL clause and its parameters. + "Given a hash map of column names and values and a clause type + (`:set`, `:where`), return a vector of a SQL clause and its parameters. - Applies any :column-fn supplied in the options." + Applies any `:column-fn` supplied in the options." [key-map clause opts] (let [entity-fn (:column-fn opts identity) [where params] (reduce-kv (fn [[conds params] k v] @@ -40,22 +44,50 @@ "Given a hash map of column names and values, return a string of all the column names. - Applies any :column-fn supplied in the options." + Applies any `:column-fn` supplied in the options." [key-map opts] (str/join ", " (map (comp (:column-fn opts identity) name) (keys key-map)))) (defn- as-? "Given a hash map of column names and values, or a vector of column names, - return a string of ? placeholders for them." + return a string of `?` placeholders for them." [key-map opts] (str/join ", " (repeat (count key-map) "?"))) +(defn- for-order-col + "Given a column name, or a pair of column name and direction, + return the sub-clause for addition to `ORDER BY`." + [col opts] + (let [entity-fn (:column-fn opts identity)] + (cond (keyword? col) + (entity-fn (name col)) + + (and (vector? col) (= 2 (count col)) (keyword? (first col))) + (str (entity-fn (name (first col))) + " " + (or (get {:asc "ASC" :desc "DESC"} (second col)) + (throw (IllegalArgumentException. + (str ":order-by " col + " expected :asc or :desc"))))) + :else + (throw (IllegalArgumentException. + (str ":order-by expected keyword or keyword pair," + " found: " col)))))) + +(defn- for-order + "Given an `:order-by` vector, return an `ORDER BY` clause." + [order-by opts] + (if (vector? order-by) + (str "ORDER BY " + (str/join ", " (map #(for-order-col % opts) order-by))) + (throw (IllegalArgumentException. ":order-by must be a vector")))) + (defn- for-query "Given a table name and either a hash map of column names and values or a vector of SQL (where clause) and its parameters, return a vector of the - full SELECT SQL string and its parameters. + full `SELECT` SQL string and its parameters. - Applies any :table-fn / :column-fn supplied in the options." + Applies any `:table-fn` / `:column-fn` supplied in the options." [table where-params opts] (let [entity-fn (:table-fn opts identity) where-params (if (map? where-params) @@ -63,15 +95,17 @@ (into [(str "WHERE " (first where-params))] (rest where-params)))] (into [(str "SELECT * FROM " (entity-fn (name table)) - " " (first where-params))] + " " (first where-params) + (when-let [order-by (:order-by opts)] + (str " " (for-order order-by opts))))] (rest where-params)))) (defn- for-delete "Given a table name and either a hash map of column names and values or a vector of SQL (where clause) and its parameters, return a vector of the - full DELETE SQL string and its parameters. + full `DELETE` SQL string and its parameters. - Applies any :table-fn / :column-fn supplied in the options." + Applies any `:table-fn` / `:column-fn` supplied in the options." [table where-params opts] (let [entity-fn (:table-fn opts identity) where-params (if (map? where-params) @@ -85,10 +119,10 @@ (defn- for-update "Given a table name, a vector of column names to set and their values, and either a hash map of column names and values or a vector of SQL (where clause) - and its parameters, return a vector of the full UPDATE SQL string and its + and its parameters, return a vector of the full `UPDATE` SQL string and its parameters. - Applies any :table-fn / :column-fn supplied in the options." + Applies any `:table-fn` / `:column-fn` supplied in the options." [table key-map where-params opts] (let [entity-fn (:table-fn opts identity) set-params (by-keys key-map :set opts) @@ -104,9 +138,9 @@ (defn- for-insert "Given a table name and a hash map of column names and their values, - return a vector of the full INSERT SQL string and its parameters. + return a vector of the full `INSERT` SQL string and its parameters. - Applies any :table-fn / :column-fn supplied in the options." + Applies any `:table-fn` / `:column-fn` supplied in the options." [table key-map opts] (let [entity-fn (:table-fn opts identity) params (as-keys key-map opts) @@ -118,10 +152,10 @@ (defn- for-insert-multi "Given a table name, a vector of column names, and a vector of row values - (each row is a vector of its values), return a vector of the full INSERT + (each row is a vector of its values), return a vector of the full `INSERT` SQL string and its parameters. - Applies any :table-fn / :column-fn supplied in the options." + Applies any `:table-fn` / `:column-fn` supplied in the options." [table cols rows opts] (assert (apply = (count cols) (map count rows))) (let [table-fn (:table-fn opts identity) @@ -136,7 +170,7 @@ rows))) (defn insert! - "Syntactic sugar over execute-one! to make inserting hash maps easier. + "Syntactic sugar over `execute-one!` to make inserting hash maps easier. Given a connectable object, a table name, and a data hash map, inserts the data as a single row in the database and attempts to return a map of generated @@ -149,7 +183,7 @@ (merge {:return-keys true} opts)))) (defn insert-multi! - "Syntactic sugar over execute! to make inserting columns/rows easier. + "Syntactic sugar over `execute!` to make inserting columns/rows easier. Given a connectable object, a table name, a sequence of column names, and a vector of rows of data (vectors of column values), inserts the data as @@ -163,7 +197,7 @@ (merge {:return-keys true} opts)))) (defn query - "Syntactic sugar over execute! to provide a query alias. + "Syntactic sugar over `execute!` to provide a query alias. Given a connectable object, and a vector of SQL and its parameters, returns a vector of hash maps of rows that match." @@ -173,10 +207,14 @@ (execute! connectable sql-params opts))) (defn find-by-keys - "Syntactic sugar over execute! to make certain common queries easier. + "Syntactic sugar over `execute!` to make certain common queries easier. Given a connectable object, a table name, and a hash map of columns and - their values, returns a vector of hash maps of rows that match." + their values, returns a vector of hash maps of rows that match. + + If the `:order-by` option is present, add `ORDER BY` clause. `:order-by` + should be a vector of column names or pairs of column name / direction, + which can be `:asc` or `:desc`." ([connectable table key-map] (find-by-keys connectable table key-map {})) ([connectable table key-map opts] diff --git a/test/next/jdbc/sql_test.clj b/test/next/jdbc/sql_test.clj index 3e1ba9c..b8ce083 100644 --- a/test/next/jdbc/sql_test.clj +++ b/test/next/jdbc/sql_test.clj @@ -29,13 +29,16 @@ (deftest test-for-query (testing "by example" - (is (= (#'sql/for-query :user {:id 9} {:table-fn sql-server :column-fn mysql}) - ["SELECT * FROM [user] WHERE `id` = ?" 9])) + (is (= (#'sql/for-query :user {:id 9} + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) + ["SELECT * FROM [user] WHERE `id` = ? ORDER BY `a`, `b` DESC" 9])) (is (= (#'sql/for-query :user {:id nil} {:table-fn sql-server :column-fn mysql}) ["SELECT * FROM [user] WHERE `id` IS NULL"]))) (testing "by where clause" - (is (= (#'sql/for-query :user ["id = ? and opt is null" 9] {:table-fn sql-server :column-fn mysql}) - ["SELECT * FROM [user] WHERE id = ? and opt is null" 9])))) + (is (= (#'sql/for-query :user ["id = ? and opt is null" 9] + {:table-fn sql-server :column-fn mysql :order-by [:a [:b :desc]]}) + [(str "SELECT * FROM [user] WHERE id = ? and opt is null" + " ORDER BY `a`, `b` DESC") 9])))) (deftest test-for-delete (testing "by example"