Resolves #290 **Build** New commands: - `gen-doc-tests` - only regenerates tests if stale, use `clean` command to force regen - `run-doc-tests` - calls gen-doc-tests then runs tests, accepts the same parameters as run-tests. Can specify `:platform` - `:cljs` - run tests under ClojureScript - otherwise Clojure where we can specify one of: `:1.9` `:1.10` `:master` I'm not sure if my use of the `:platform` parameter jives with your `:aliases` parameter used for `run-tests`. Can adjust if you like. Example usages: ```shell clojure -T:build gen-doc-tests clojure -T:build run-doc-tests :platform :cljs clojure -T:build run-doc-tests clojure -T:build run-doc-tests :platform :1.10 ``` The `ci` command has been updated to generate and run doc tests for same platforms as unit tests. **Articles** In addition to `README.md`, now testing doc blocks in all articles under `doc` dir excepting `doc/operator-reference.md` which does not have any runnable code blocks. **Skipped** Any code block that is intentionally not runnable has been marked to be skipped via: `<!-- :test-doc-blocks/skip -->`. **Consistency** I noticed that some code blocks use REPL syntax: ```Clojure user=> (+ 1 2 3) 6 ``` and others use editor syntax: ```Clojure (+ 1 2 3) ;;=> 6 ``` some places also omit the comment for editor style: ```Clojure (+ 1 2 3) => 6 ``` All of this is just fine with test-doc-blocks. I left the inconsistency as is, but can make a pass for consistency upon request. **HoneySQL state** I noticed a code block that set the sql dialect was affecting other tests. I simply restored the dialect to the default at the end of the code block. **Un-tweaked output** Some code blocks had string output hand-tweaked for readability. These have been adjusted to instead use `sql/format`'s `:pretty` option. In some cases the output is not as readable as the hand-tweaked version. I humbly suggest that perhaps `:pretty` output could perhaps be improved (instead of having test-doc-blocks somehow adapt). **Corrections** There were very few code blocks that required fixing due to incorrect output/code. Please review the diffs carefully to make sure all is as expected. **refer-clojure :excludes** Not currently supported for test-doc-blocks, not a real issue for Clojure, we'll see warnings under Clojure, but that's probably ok. But I might actually need it for ClojureScript. I was finding that `for` did not get overridden by our helper `:refer` in CloureScript. Will add proper support to test-doc-blocks but in the short-term, will use `h/for`. **ns requires adjustments** Any specific case of `(ns my-ns (require [my-require :as a]))` is now the REPL friendly `(require '[my-require :as a])` Any missing required `requires` were added. The HoneySQL docs seem to encourage the use of referred vars for helpers. Although this has the con of overlaps with Clojure core vars, it is also convenient for Clojure when using `:refer :all`. **ClojureScript :refer** ClojureScript does not support `:refer :all` and each var must be specified in place of `:all`. I have adjusted examples accordingly to work with both Clojure and ClojureScript.
10 KiB
SQL Special Syntax
This section lists the function-like expressions that HoneySQL supports out of the box which are formatted as special syntactic forms.
The first group are used for SQL expressions. The second (last group) are used primarily in column definitions (as part of :with-columns and :add-column / :modify-column).
array
Accepts a single argument, which is expected to evaluate to
a sequence, and produces ARRAY[?, ?, ..] for the elements
of that sequence (as SQL parameters):
(require '[honey.sql :as sql])
(sql/format-expr [:array (range 5)])
;;=> ["ARRAY[?, ?, ?, ?, ?]" 0 1 2 3 4]
between
Accepts three arguments: an expression, a lower bound, and an upper bound:
(sql/format-expr [:between :id 1 100])
;;=> ["id BETWEEN ? AND ?" 1 100]
case
A SQL CASE expression. Expects an even number of arguments:
alternating condition and result expressions. A condition
may be :else (or 'else) to produce ELSE, otherwise
WHEN <condition> THEN <result> will be produced:
(sql/format-expr [:case [:< :a 10] "small" [:> :a 100] "big" :else "medium"])
;; => ["CASE WHEN a < ? THEN ? WHEN a > ? THEN ? ELSE ? END" 10 "small" 100 "big" "medium"]
cast
A SQL CAST expression. Expects an expression and something that produces a SQL type:
(sql/format-expr [:cast :a :int])
;;=> ["CAST(a AS int)"]
composite
Accepts any number of expressions and produces a composite expression (comma-separated, wrapped in parentheses):
(sql/format-expr [:composite :a :b "red" [:+ :x 1]])
;;=> ["(a, b, ?, x + ?)" "red" 1]
distinct
Accepts a single expression and prefixes it with DISTINCT :
(sql/format {:select [ [[:count [:distinct :status]] :n] ] :from :table})
;;=> ["SELECT COUNT(DISTINCT status) AS n FROM table"]
entity
Accepts a single keyword or symbol argument and produces a SQL entity. This is intended for use in contexts that would otherwise produce a sequence of SQL keywords, such as when constructing DDL statements.
[:tablespace :quux]
;;=> TABLESPACE QUUX
[:tablespace [:entity :quux]]
;;=> TABLESPACE quux
escape
Intended to be used with regular expression patterns to specify the escape characters (if any).
(sql/format {:select :* :from :foo
:where [:similar-to :foo [:escape "bar" [:inline "*"]]]})
;;=> ["SELECT * FROM foo WHERE foo SIMILAR TO ? ESCAPE '*'" "bar"]
filter, within-group
Used to produce PostgreSQL's FILTER and WITHIN GROUP expressions.
See also order-by below.
These both accept a SQL expression followed by a SQL clause.
Filter generally expects an aggregate expression and a WHERE clause.
Within group generally expects an aggregate expression and an ORDER BY clause.
(sql/format {:select [:a :b [[:filter :%count.* {:where [:< :x 100]}] :c]
[[:within-group [:percentile_disc [:inline 0.25]]
{:order-by [:a]}] :inter_max]
[[:within-group [:percentile_cont [:inline 0.25]]
{:order-by [:a]}] :abs_max]]
:from :aa}
{:pretty true})
;;=> ["
SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max
FROM aa
"
100]
There are helpers for both filter and within-group. Be careful with filter
since it shadows clojure.core/filter:
(require '[honey.sql.helpers :refer [select filter within-group from order-by where]])
(sql/format (-> (select :a :b [(filter :%count.* (where :< :x 100)) :c]
[(within-group [:percentile_disc [:inline 0.25]]
(order-by :a)) :inter_max]
[(within-group [:percentile_cont [:inline 0.25]]
(order-by :a)) :abs_max])
(from :aa))
{:pretty true})
;;=> ["
SELECT a, b, COUNT(*) FILTER (WHERE x < ?) AS c, PERCENTILE_DISC(0.25) WITHIN GROUP (ORDER BY a ASC) AS inter_max, PERCENTILE_CONT(0.25) WITHIN GROUP (ORDER BY a ASC) AS abs_max
FROM aa
"
100]
inline
Accepts a single argument and tries to render it as a SQL value directly in the formatted SQL string rather than turning it into a positional parameter:
nilbecomesNULL- keywords and symbols become upper case entities (with
-replaced by space) - strings become inline SQL strings (with single quotes)
- a sequence has each element formatted inline and then joined with spaces
- all other values are just rendered via Clojure's
strfunction
(sql/format {:where [:= :x [:inline "foo"]]})
;;=> ["WHERE x = 'foo'"]
interval
Accepts two arguments: an expression and a keyword (or a symbol)
that represents a time unit. Produces an INTERVAL expression:
(sql/format-expr [:date_add [:now] [:interval 30 :days]])
;;=> ["DATE_ADD(NOW(), INTERVAL ? DAYS)" 30]
lateral
Accepts a single argument that can be a (SELECT) clause or
a (function call) expression. Produces a LATERAL subquery
clause based on the SELECT clause or the SQL expression.
lift
Used to wrap a Clojure value that should be passed as a SQL parameter but would otherwise be treated as a SQL expression or statement, i.e., a sequence or hash map. This can be useful when dealing with JSON types:
(sql/format {:where [:= :json-col [:lift {:a 1 :b "two"}]]})
;;=> ["WHERE json_col = ?" {:a 1 :b "two"}]
Note: HoneySQL 1.x used
honeysql.format/valuefor this.
nest
Used to wrap an expression when you want an extra level of parentheses around it:
(sql/format {:where [:= :x 42]})
;;=> ["WHERE x = ?" 42]
(sql/format {:where [:nest [:= :x 42]]})
;;=> ["WHERE (x = ?)" 42]
:nest is also supported as a SQL clause for the same reason.
not
Accepts a single expression and formats it with NOT
in front of it:
(sql/format-expr [:not nil])
;;=> ["NOT NULL"]
(sql/format-expr [:not [:= :x 42]])
;;=> ["NOT x = ?" 42]
order-by
In addition to the ORDER BY clause, HoneySQL also supports ORDER BY
in an expression (for PostgreSQL). It accepts a SQL expression followed
by an ordering specifier, which can be an expression or a pair of expression
and direction (:asc or :desc):
(sql/format {:select [[[:array_agg [:order-by :a [:b :desc]]]]] :from :table})
;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"]
(sql/format (-> (select [[:array_agg [:order-by :a [:b :desc]]]])
(from :table)))
;;=> ["SELECT ARRAY_AGG(a ORDER BY b DESC) FROM table"]
(sql/format {:select [[[:string_agg :a [:order-by [:inline ","] :a]]]] :from :table})
;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"]
(sql/format (-> (select [[:string_agg :a [:order-by [:inline ","] :a]]])
(from :table)))
;;=> ["SELECT STRING_AGG(a, ',' ORDER BY a ASC) FROM table"]
There is no helper for the ORDER BY special syntax: the order-by helper
only produces a SQL clause.
over
This is intended to be used with the :window and :partition-by clauses.
:over takes any number of window expressions which are either pairs or triples
that have an aggregation expression, a window function, and an optional alias.
The window function may either be a SQL entity (named in a :window clause)
or a SQL clause that describes the window (e.g., using :partition-by and/or :order-by).
Since a function call (using :over) needs to be wrapped in a sequence for a
:select clause, it is usually easier to use the over helper function
to construct this expression.
param
Used to identify a named parameter in a SQL expression
as an alternative to a keyword (or a symbol) that begins
with ?:
(sql/format {:where [:= :x :?foo]} {:params {:foo 42}})
;;=> ["WHERE x = ?" 42]
(sql/format {:where [:= :x [:param :foo]]} {:params {:foo 42}})
;;=> ["WHERE x = ?" 42]
raw
Accepts a single argument and renders it as literal SQL in the formatted string:
(sql/format {:select [:a [[:raw "@var := foo"]]]})
;;=> ["SELECT a, @var := foo"]
If the argument is a sequence of expressions, they will each be rendered literally and joined together (with no spaces):
(sql/format {:select [:a [[:raw ["@var" " := " "foo"]]]]})
;;=> ["SELECT a, @var := foo"]
When a sequence of expressions is supplied, any subexpressions that are, in turn, sequences will be formatted as regular SQL expressions and that SQL will be joined into the result, along with any parameters from them:
(sql/format {:select [:a [[:raw ["@var := " [:inline "foo"]]]]]})
;;=> ["SELECT a, @var := 'foo'"]
(sql/format {:select [:a [[:raw ["@var := " ["foo"]]]]]})
;;=> ["SELECT a, @var := (?)" "foo"]
:raw is also supported as a SQL clause for the same reason.
Column Descriptors
There are three types of descriptors that vary in how they treat their first argument. All three descriptors automatically try to inline any parameters (and will throw an exception if they can't, since these descriptors are meant to be used in column or index specifications).
foreign-key, primary-key
If no arguments are provided, these render as just SQL keywords (uppercase):
[:foreign-key] ;=> FOREIGN KEY
[:primary-key] ;=> PRIMARY KEY
Otherwise, these render as regular function calls:
[:foreign-key :a] ;=> FOREIGN KEY(a)
[:primary-key :x :y] ;=> PRIMARY KEY(x, y)
constraint, default, references
Although these are grouped together, they are generally used differently. This group renders as SQL keywords if no arguments are provided. If a single argument is provided, this renders as a SQL keyword followed by the argument. If two or more arguments are provided, this renders as a SQL keyword followed by the first argument, followed by the rest as a regular argument list:
[:default] ;=> DEFAULT
[:default 42] ;=> DEFAULT 42
[:default "str"] ;=> DEFAULT 'str'
[:constraint :name] ;=> CONSTRAINT name
[:references :foo :bar] ;=> REFERENCES foo(bar)
index, unique
These behave like the group above except that if the
first argument is nil, it is omitted:
[:index :foo :bar :quux] ;=> INDEX foo(bar, quux)
[:index nil :bar :quux] ;=> INDEX(bar, quux)
[:unique :a :b] ;=> UNIQUE a(b)