diff --git a/CHANGELOG.md b/CHANGELOG.md index 856d139..8acda14 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -5,6 +5,7 @@ Only accretive/fixative changes will be made from now on. Changes made since the 1.0.478 release: * Address #124 by extending `next.jdbc.sql.builder/for-query` to support `:top` (SQL Server), `:limit` / `:offset` (MySQL/PostgreSQL), `:offset` / `:fetch` (SQL Standard). * Allow `:all` to be passed into `find-by-keys` instead of an example hash map or a where clause vector so all rows will be returned (expected to be used with `:offset` etc to support simple pagination of an entire table). +* Add `:columns` option to `find-by-keys` (and `get-by-id`) to specify a subset of columns to be returned in each row. This can also specify an alias for the column and allows for computed expressions to be selected with an alias. ## Stable Builds diff --git a/doc/all-the-options.md b/doc/all-the-options.md index 4ff64cb..e9608fe 100644 --- a/doc/all-the-options.md +++ b/doc/all-the-options.md @@ -43,9 +43,14 @@ They also support a `:suffix` argument which can be used to specify a SQL string In addition, `find-by-keys` accepts the following options (see its docstring for more details): +* `:columns` -- specify one or more columns to `SELECT` to override selecting all columns, * `:order-by` -- specify one or more columns, on which to sort the results, * `:top` / `:limit` / `:offset` / `:fetch` to support pagination of results. +In the simple case, the `:columns` option expects a vector of keywords and each will be processed according to `:column-fn`, if provided. A column alias can be specified using a vector pair of keywords and both will be processed according to `:column-fn`, e.g., `[:foo [:bar :quux]]` would expand to `foo, bar AS quux`. You can also specify the first element of the pair as a string which will be used as-is in the generated SQL, e.g., `[:foo ["COUNT(*)" :total]]` would expand to `foo, COUNT(*) AS total`. In the latter case, the alias keyword will still be processed according to `:column-fn` but the string will be untouched -- you are responsible for any quoting and/or other formatting that might be required to produce a valid SQL expression. + +> 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. + ## Generating Rows and Result Sets Any function that might realize a row or a result set will accept: diff --git a/src/next/jdbc/specs.clj b/src/next/jdbc/specs.clj index a442cd2..6d63ea2 100644 --- a/src/next/jdbc/specs.clj +++ b/src/next/jdbc/specs.clj @@ -70,12 +70,22 @@ (s/def ::key-map (s/map-of keyword? any?)) (s/def ::example-map (s/map-of keyword? any? :min-count 1)) +;; can be a simple column name (keyword) or a pair of something and as alias +;; and that something can be a simple column name (keyword) or an arbitrary +;; expression (string) where we assume you know what you're doing +(s/def ::column-spec (s/or :column keyword? + :alias (s/and vector? + (s/cat :expr (s/or :col keyword? + :str string?) + :column keyword?)))) +(s/def ::columns (s/coll-of ::column-spec :kind vector?)) + (s/def ::order-by-col (s/or :col keyword? :dir (s/cat :col keyword? :dir #{:asc :desc}))) (s/def ::order-by (s/coll-of ::order-by-col :kind vector? :min-count 1)) (s/def ::opts-map (s/and (s/map-of keyword? any?) - (s/keys :opt-un [::order-by]))) + (s/keys :opt-un [::columns ::order-by]))) (s/def ::transactable any?) diff --git a/src/next/jdbc/sql.clj b/src/next/jdbc/sql.clj index 4b77fc0..882ddd3 100644 --- a/src/next/jdbc/sql.clj +++ b/src/next/jdbc/sql.clj @@ -85,6 +85,9 @@ If `:all` is passed instead of a hash map or vector -- the query will select all rows in the table, subject to any pagination options below. + If `:columns` is passed, only that specified subset of columns will be + returned in each row (otherwise all columns are selected). + If the `:order-by` option is present, add an `ORDER BY` clause. `:order-by` should be a vector of column names or pairs of column name / direction, which can be `:asc` or `:desc`. @@ -114,6 +117,9 @@ By default, the primary key is assumed to be `id` but that can be overridden in the five-argument call. + As with `find-by-keys`, you can specify `:columns` to return just a + subset of the columns in the returned row. + Technically, this also supports `:order-by`, `:top`, `:limit`, `:offset`, and `:fetch` -- like `find-by-keys` -- but they don't make as much sense here since only one row is ever returned." diff --git a/src/next/jdbc/sql/builder.clj b/src/next/jdbc/sql/builder.clj index 53ae646..b2f7a5f 100644 --- a/src/next/jdbc/sql/builder.clj +++ b/src/next/jdbc/sql/builder.clj @@ -13,16 +13,46 @@ (defn as-? "Given a hash map of column names and values, or a vector of column names, return a string of `?` placeholders for them." - [key-map opts] + [key-map _] (str/join ", " (repeat (count key-map) "?"))) +(defn as-cols + "Given a sequence of raw column names, return a string of all the + formatted column names. + + If a raw column name is a keyword, apply `:column-fn` to its name, + from the options if present. + + If a raw column name is a vector pair, treat it as an expression with + an alias. If the first item is a keyword, apply `:column-fn` to its + name, else accept it as-is. The second item should be a keyword and + that will have `:column-fn` applied to its name. + + This allows columns to be specified as simple names, e.g., `:foo`, + as simple aliases, e.g., `[:foo :bar]`, or as expressions with an + alias, e.g., `[\"count(*)\" :total]`." + [cols opts] + (let [col-fn (:column-fn opts identity)] + (str/join ", " (map (fn [raw] + (if (vector? raw) + (if (keyword? (first raw)) + (str (col-fn (name (first raw))) + " AS " + (col-fn (name (second raw)))) + (str (first raw) + " AS " + (col-fn (name (second raw))))) + (col-fn (name raw)))) + cols)))) + + (defn as-keys "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." [key-map opts] - (str/join ", " (map (comp (:column-fn opts identity) name) (keys key-map)))) + (as-cols (keys key-map) opts)) (defn by-keys "Given a hash map of column names and values and a clause type @@ -148,6 +178,12 @@ Applies any `:table-fn` / `:column-fn` supplied in the options. + Handles pagination options (`:top`, `:limit` / `:offset`, or `:offset` / + `:fetch`) for SQL Server, MySQL / SQLite, ANSI SQL respectively. + + By default, this selects all columns, but if the `:columns` option is + present the select will only be those columns. + If `:suffix` is provided in `opts`, that string is appended to the `SELECT ...` statement." [table where-params opts] @@ -169,7 +205,10 @@ (into [(str "SELECT " (when (:top opts) "TOP ? ") - "* FROM " (entity-fn (name table)) + (if-let [cols (seq (:columns opts))] + (as-cols cols opts) + "*") + " FROM " (entity-fn (name table)) (when-let [clause (first where-params)] (str " " clause)) (when-let [order-by (:order-by opts)] diff --git a/test/next/jdbc/sql/builder_test.clj b/test/next/jdbc/sql/builder_test.clj index d02d419..82e6132 100644 --- a/test/next/jdbc/sql/builder_test.clj +++ b/test/next/jdbc/sql/builder_test.clj @@ -16,6 +16,14 @@ (is (= (builder/by-keys {:a nil :b 42 :c "s"} :set {}) ["SET a = ?, b = ?, c = ?" nil 42 "s"])))) +(deftest test-as-cols + (is (= (builder/as-cols [:a :b :c] {}) + "a, b, c")) + (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {}) + "a AS aa, b, count(*) AS c")) + (is (= (builder/as-cols [[:a :aa] :b ["count(*)" :c]] {:column-fn mysql}) + "`a` AS `aa`, `b`, count(*) AS `c`"))) + (deftest test-as-keys (is (= (builder/as-keys {:a nil :b 42 :c "s"} {}) "a, b, c"))) diff --git a/test/next/jdbc/sql_test.clj b/test/next/jdbc/sql_test.clj index 8993ebb..d19a879 100644 --- a/test/next/jdbc/sql_test.clj +++ b/test/next/jdbc/sql_test.clj @@ -8,6 +8,7 @@ [next.jdbc.sql :as sql] [next.jdbc.test-fixtures :refer [with-test-db ds column default-options + db derby? jtds? maria? mssql? mysql? postgres? sqlite?]] [next.jdbc.types :refer [as-other as-real as-varchar]])) @@ -28,16 +29,24 @@ (deftest test-find-all-offset (let [ds-opts (jdbc/with-options (ds) (default-options)) - rs (sql/find-by-keys ds-opts :fruit :all - (assoc (if (or (mysql?) (sqlite?)) - {:limit 2 :offset 1} - {:offset 1 :fetch 2}) - :order-by [:id]))] + rs (sql/find-by-keys + ds-opts :fruit :all + (assoc + (if (or (mysql?) (sqlite?)) + {:limit 2 :offset 1} + {:offset 1 :fetch 2}) + :columns [:ID + ["CASE WHEN grade > 91 THEN 'ok ' ELSE 'bad' END" + :QUALITY]] + :order-by [:id]))] (is (= 2 (count rs))) (is (every? map? rs)) (is (every? meta rs)) + (is (every? #(= 2 (count %)) rs)) (is (= 2 ((column :FRUIT/ID) (first rs)))) - (is (= 3 ((column :FRUIT/ID) (last rs)))))) + (is (= "ok " ((column :QUALITY) (first rs)))) + (is (= 3 ((column :FRUIT/ID) (last rs)))) + (is (= "bad" ((column :QUALITY) (last rs)))))) (deftest test-find-by-keys (let [ds-opts (jdbc/with-options (ds) (default-options))]