2021-02-02 22:50:12 +00:00
# SQL Clauses Supported
This section lists all the SQL clauses that HoneySQL
supports out of the box, in the order that they are
processed for formatting.
Clauses can be specified as keywords or symbols. Use
`-` in the clause name where the formatted SQL would have
a space (e.g., `:left-join` is formatted as `LEFT JOIN` ).
Except as noted, these clauses apply to all the SQL
dialects that HoneySQL supports.
## nest
2021-02-06 17:00:46 +00:00
This is pseudo-syntax that lets you wrap a substatement
in an extra level of parentheses. It should rarely be
needed and it is mostly present to provide the same
functionality for clauses that `[:nest ..]` provides
for expressions.
2021-02-02 22:50:12 +00:00
## with, with-recursive
2021-02-06 17:00:46 +00:00
These provide CTE support for SQL Server. The argument to
`:with` (or `:with-recursive` ) is a pair of
a result set name (or description) and a basic SQL statement.
The result set can either be a SQL entity (a simple name)
or a pair of a SQL entity and a set of column names.
```clojure
user=> (sql/format '{with (stuff {select (:*) from (foo)})
select (id,name)
from (stuff)
where (= status 0)})
["WITH stuff AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0]
```
You can specify a list of columns for the CTE like this:
```clojure
user=> (sql/format {:with [[:stuff {:columns [:id :name]}]
{:select [:*] :from [:foo]}]
:select [:id :name]
:from [:stuff]
:where [:= :status 0]})
["WITH stuff (id, name) AS (SELECT * FROM foo) SELECT id, name FROM stuff WHERE status = ?" 0]
```
You can use a `VALUES` clause in the CTE:
```clojure
user=> (sql/format {:with [[:stuff {:columns [:id :name]}]
{:values [[1 "Sean"] [2 "Jay"]]}]
:select [:id :name]
:from [:stuff]})
["WITH stuff (id, name) AS (VALUES (?, ?), (?, ?)) SELECT id, name FROM stuff" 1 "Sean" 2 "Jay"]
```
`:with-recursive` follows the same rules as `:with` and produces `WITH RECURSIVE` instead of just `WITH` .
> Note: HoneySQL 0.6.2 introduced support for CTEs a long time ago and it expected the pair (of result set and query) to be wrapped in a sequence, even though you can only have a single CTE. For backward compatibility, HoneySQL 2.0 accepts that format but it should be considered deprecated.
2021-02-02 22:50:12 +00:00
## intersect, union, union-all, except, except-all
2021-02-07 11:40:29 +00:00
These all expect a sequence of SQL clauses, those clauses
will be wrapped in parentheses, and the SQL keyword interspersed
between those clauses.
```clojure
user=> (sql/format '{union [{select (id,status) from (table-a)}
{select (id,(event status) from (table-b))}]})
["(SELECT id, status FROM table_a) UNION (SELECT id, event AS status, from, table_b)"]
```
2021-02-02 22:50:12 +00:00
## select, select-distinct
2021-02-07 11:40:29 +00:00
`:select` expects a sequence of SQL entities (column names
or expressions). Any of the SQL entities can be a pair of entity and alias. If you are selecting an expression, you would most
often provide an alias for the expression, but it can be omitted
as in the following:
```clojure
user=> (sql/format '{select (id, ((* cost 2)), (event status))
from (table)})
["SELECT id, cost * ?, event AS status FROM table" 2]
```
With an alias on the expression:
```clojure
user=> (sql/format {:select [:id, [[:* :cost 2] :total], [:event :status]]
:from [:table]})
["SELECT id, cost * ? AS total, event AS status FROM table" 2]
```
`:select-distinct` works the same way but produces `SELECT DISTINCT` .
2021-02-07 16:41:11 +00:00
HoneySQL does not yet support `SELECT .. INTO ..`
or `SELECT .. BULK COLLECT INTO ..` .
2021-02-02 22:50:12 +00:00
## insert-into
2021-02-07 11:40:29 +00:00
There are two use cases with `:insert-into` . The first case
takes just a simple SQL entity (the table name). The more
complex case takes a pair of a SQL entity and a SQL query.
In that second case, you can specify the columns by using
a pair of the table name and a sequence of column names.
For the first case, you'll use the `:values` clause and you
may use the `:columns` clause as well.
```clojure
user=> (sql/format {:insert-into :transport
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
["INSERT INTO transport VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
user=> (sql/format {:insert-into :transport
:columns [:id :name]
:values [[1 "Car"] [2 "Boat"] [3 "Bike"]]})
["INSERT INTO transport (id, name) VALUES (?, ?), (?, ?), (?, ?)" 1 "Car" 2 "Boat" 3 "Bike"]
```
The second case:
```clojure
user=> (sql/format '{insert-into (transport {select (id, name) from (cars)})})
["INSERT INTO transport SELECT id, name FROM cars"]
user=> (sql/format '{insert-into ((transport (id, name)) {select (*) from (cars)})})
["INSERT INTO transport (id, name) SELECT * FROM cars"]
```
2021-02-02 22:50:12 +00:00
## update
2021-02-07 11:40:29 +00:00
`:update` expects either a simple SQL entity (table name)
or a pair of the table name and an alias:
```clojure
user=> (sql/format {:update :transport
:set {:name "Yacht"}
:where [:= :id 2]})
["UPDATE transport SET name = ? WHERE id = ?" "Yacht" 2]
```
2021-02-02 22:50:12 +00:00
## delete, delete-from
2021-02-07 11:40:29 +00:00
`:delete-from` is the simple use case here, accepting just a
SQL entity (table name). `:delete` allows for deleting from
multiple tables, accepting a sequence of either table names
or aliases:
```clojure
user=> (sql/format '{delete-from transport where (= id 1)})
["DELETE FROM transport WHERE id = ?" 1]
user=> (sql/format {:delete [:order :item]
:from [:order]
:join [:item [:= :order.item-id :item.id]]
:where [:= :item.id 42]})
["DELETE order, item FROM order INNER JOIN item ON order.item_id = item.id WHERE item.id = ?" 42]
```
2021-02-02 22:50:12 +00:00
## truncate
2021-02-07 11:40:29 +00:00
`:truncate` accepts a simple SQL entity (table name):
```clojure
user=> (sql/format '{truncate transport})
["TRUNCATE transport"]
```
2021-02-02 22:50:12 +00:00
## columns
2021-02-07 11:40:29 +00:00
Wherever you need just a list of column names `:columns`
accepts a sequence of SQL entities (names). We saw an
example above with `:insert-into` .
2021-02-02 22:50:12 +00:00
## set (ANSI)
2021-02-07 11:40:29 +00:00
`:set` accepts a hash map of SQL entities and the values
that they should be assigned. This precedence -- between
`:columns` and `:from` -- corresponds to ANSI SQL which
is correct for most databases. The MySQL dialect that
HoneySQL 2.0 supports has a different precedence (below).
```clojure
user=> (sql/format {:update :order
:set {:line-count [:+ :line-count 1]}
:where [:= :item-id 42]})
["UPDATE order SET line_count = line_count + ? WHERE item_id = ?" 1 42]
```
2021-02-02 22:50:12 +00:00
## from
2021-02-07 11:40:29 +00:00
`:from` accepts a single sequence argument that lists
one or more SQL entities. Each entity can either be a
simple table name (keyword or symbol) or a pair of a
table name and an alias:
```clojure
user=> (sql/format {:select [:username :name]
:from [:user :status]
:where [:and [:= :user.statusid :status.id]
[:= :user.id 9]]})
["SELECT username, name FROM user, status WHERE (user.statusid = status.id) AND (user.id = ?)" 9]
user=> (sql/format {:select [:u.username :s.name]
:from [[:user :u] [:status :s]]
:where [:and [:= :u.statusid :s.id]
[:= :u.id 9]]})
["SELECT u.username, s.name FROM user AS u, status AS s WHERE (u.statusid = s.id) AND (u.id = ?)" 9]
```
2021-02-08 00:36:52 +00:00
> Note: the actual formatting of a `:from` clause is currently identical to the formatting of a `:select` clause.
2021-02-02 22:50:12 +00:00
## using
2021-02-07 11:40:29 +00:00
2021-02-08 00:36:52 +00:00
`:using` accepts a single sequence argument that lists
one or more SQL entities. Each entity can either be a
simple table name (keyword or symbol) or a pair of a
table name and an alias.
`:using` is intended to be used as a simple join with a `:delete-from`
clause (see [PostgreSQL DELETE statement ](https://www.postgresql.org/docs/12/sql-delete.html )
for more detail).
> Note: the actual formatting of a `:using` clause is currently identical to the formatting of a `:select` clause.
2021-02-02 22:50:12 +00:00
## join, left-join, right-join, inner-join, outer-join, full-join
2021-02-07 11:40:29 +00:00
2021-02-07 13:13:39 +00:00
All these join clauses have the same structure: they accept a sequence
of alternating SQL entities (table names) and conditions that specify
how to perform the join. The table names can either be simple names
or a pair of a table name and an alias:
```clojure
user=> (sql/format {:select [:u.username :s.name]
:from [[:user :u]]
:join [[:status :s] [:= :u.statusid :s.id]]
:where [:= :s.id 2]})
["SELECT u.username, s.name FROM user AS u INNER JOIN status AS s ON u.statusid = s.id WHERE s.id = ?" 2]
```
An alternative to a join condition is a `USING` expression:
```clojure
user=> (sql/format {:select [:t.ref :pp.code]
:from [[:transaction :t]]
:left-join [[:paypal-tx :pp]
[:using :id]]
:where [:= "settled" :pp.status]})
["SELECT t.ref, pp.code FROM transaction AS t LEFT JOIN paypal_tx AS pp USING (id) WHERE ? = pp.status" "settled"]
```
2021-02-02 22:50:12 +00:00
## cross-join
2021-02-07 11:40:29 +00:00
2021-02-07 16:41:11 +00:00
`:cross-join` accepts a single sequence argument that lists
one or more SQL entities. Each entity can either be a
simple table name (keyword or symbol) or a pair of a
table name and an alias.
> Note: the actual formatting of a `:cross-join` clause is currently identical to the formatting of a `:select` clause.
2021-02-02 22:50:12 +00:00
## set (MySQL)
2021-02-07 11:40:29 +00:00
2021-02-07 12:47:31 +00:00
This is the precedence of the `:set` clause for the MySQL dialect.
It is otherwise identical to the `:set` clause described above.
2021-02-02 22:50:12 +00:00
## where
2021-02-07 11:40:29 +00:00
2021-02-07 12:47:31 +00:00
The `:where` clause can have a single SQL expression, or
a sequence of SQL expressions prefixed by either `:and`
or `:or` . See examples of `:where` in various clauses above.
2021-02-02 22:50:12 +00:00
## group-by
2021-02-07 11:40:29 +00:00
2021-02-07 12:47:31 +00:00
`:group-by` accepts a sequence of one or more SQL expressions.
```clojure
user=> (sql/format '{select (*) from (table)
group-by (status, (year created-date))})
["SELECT * FROM table GROUP BY status, YEAR(created_date)"]
```
2021-02-02 22:50:12 +00:00
## having
2021-02-07 11:40:29 +00:00
2021-02-07 12:47:31 +00:00
The `:having` clause works identically to `:where` above
but is rendered into the SQL later in precedence order.
2021-02-02 22:50:12 +00:00
## order-by
2021-02-07 11:40:29 +00:00
2021-02-07 12:47:31 +00:00
`:order-by` accepts a sequence of one or more ordering
expressions. Each ordering expression is either a simple
SQL entity or a pair of a SQL expression and a direction
(which can be `:asc` or `:desc` -- or the symbol equivalent).
If you want to order by an expression, you should wrap it
as a pair with a direction:
```clojure
user=> (sql/format '{select (*) from table
;; simple orderings:
order-by (status, created-date)})
["SELECT * FROM table ORDER BY status ASC, created_date ASC"]
user=> (sql/format '{select (*) from table
;; explicit direction provided:
order-by ((status asc), ((year created-date) asc))})
["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"]
```
The default direction is ascending and if you provide a wrapped
expression you _can_ omit the direction if you want:
```clojure
user=> (sql/format {:select [:*] :from :table
;; expression without direction is still wrapped:
:order-by [:status, [[:year :created-date]]]})
["SELECT * FROM table ORDER BY status ASC, YEAR(created_date) ASC"]
```
2021-02-02 22:50:12 +00:00
## limit, offset (MySQL)
2021-02-07 11:40:29 +00:00
2021-02-08 20:48:42 +00:00
Both `:limit` and `:offset` expect a single SQL expression:
```clojure
user=> (sql/format {:select [:id :name]
:from [:table]
:limit 20 :offset 20})
["SELECT id, name FROM table LIMIT ? OFFSET ?" 20 20]
```
> Note: In the prerelease, these MySQL-specific clauses are in the default dialect but these will be moved to the `:mysql` dialect.
2021-02-02 22:50:12 +00:00
## for
2021-02-07 11:40:29 +00:00
2021-02-08 20:48:42 +00:00
The `:for` clause accepts either a single item -- the lock
strength -- or a sequence of up to three items of which the
first is the lock strength, followed by an optional table
name (or sequence of table names), followed by how to deal
with the lock:
```clojure
user=> (sql/format '{select (*) from (table)
for update})
["SELECT * FROM table FOR UPDATE"]
user=> (sql/format '{select (*) from (table)
for no-key-update})
["SELECT * FROM table FOR NO KEY UPDATE"]
user=> (sql/format '{select (*) from (table)
for (key-share wait)})
["SELECT * FROM table FOR KEY SHARE WAIT"]
user=> (sql/format '{select (*) from (table)
for (update bar wait)})
["SELECT * FROM table FOR UPDATE OF bar WAIT"]
user=> (sql/format '{select (*) from (table)
for (update (bar quux) wait)})
["SELECT * FROM table FOR UPDATE OF bar, quux WAIT"]
```
The lock strength can be any SQL keyword or phrase
represented as a Clojure keyword (or symbol), with
spaces represented by `-` .
The three SQL keywords/phrases that are recognized
as not being a table name in the second slot are
`NOWAIT` , `SKIP LOCKED` , and `WAIT` .
However, in the case where a table name (or sequence
of table names) is present, no check is made on the
keyword or phrase in that third slot (although it is
expected to be just one of those three mentioned above).
2021-02-02 22:50:12 +00:00
## lock (MySQL)
2021-02-07 11:40:29 +00:00
2021-02-08 20:48:42 +00:00
The syntax accepted for MySQL's `:lock` is exactly the
same as the `:for` clause above.
> Note: In the prerelease, this MySQL-specific clauses is in the default dialect but this will be moved to the `:mysql` dialect.
2021-02-02 22:50:12 +00:00
## values
2021-02-07 11:40:29 +00:00
2021-02-07 16:41:11 +00:00
`:values` accepts either a sequence of hash maps representing
row values or a sequence of sequences, also representing row
values.
In the former case, all of the rows are augmented to have
`nil` values for any missing keys (columns). In the latter,
all of the rows are padded to the same length by adding `nil`
values if needed.
```clojure
user=> (sql/format {:insert-into :table
:values [[1 2] [2 3 4 5] [3 4 5]]})
["INSERT INTO table VALUES (?, ?, NULL, NULL), (?, ?, ?, ?), (?, ?, ?, NULL)" 1 2 2 3 4 5 3 4 5]
user=> (sql/format '{insert-into table
values ({id 1 name "Sean"}
{id 2}
{name "Extra"})})
["INSERT INTO table (id, name) VALUES (?, ?), (?, NULL), (NULL, ?)" 1 "Sean" 2 "Extra"]
```
2021-02-02 22:50:12 +00:00
## on-conflict, on-constraint, do-nothing, do-update-set
2021-02-07 11:40:29 +00:00
2021-02-08 20:48:42 +00:00
These are grouped together because they are handled
as if they are separate clauses but they will appear
in pairs: `ON ... DO ...` .
`:on-conflict` accepts either a single SQL entity
(a keyword or symbol) or a SQL clause. That's either
a column name or an `:on-constraint` clause or a
`:where` clause.
`:on-constraint` accepts a single SQL entity that
identifies a constraint name.
Since `:do-nothing` is a SQL clause but has no
associated data, it still has to have an arbitrary
value because clauses are hash maps and that value
will be ignored so `:do-nothing true` is a
reasonable choices.
`:do-update-set` accepts either a single SQL entity
(a keyword or symbol) or hash map of columns and
values, like `:set` (above). The former produces
a `SET` clause using `EXCLUDED` :
```clojure
user=> (sql/format {:insert-into :companies
:values [{:name "Microsoft"}]
:on-conflict :name
:do-update-set :name})
["INSERT INTO companies (name) VALUES (?) ON CONFLICT (name) DO UPDATE SET name = EXCLUDED.name" "Microsoft"]
user=> (sql/format {:insert-into :companies
:values [{:name "Microsoft"}]
:on-conflict {:on-constraint :name-idx}
:do-nothing true})
["INSERT INTO companies (name) VALUES (?) ON CONFLICT ON CONSTRAINT name_idx DO NOTHING" "Microsoft"]
```
2021-02-07 11:40:29 +00:00
## returning
2021-02-07 16:41:11 +00:00
`:returning` accepts a single sequence argument that lists
one or more SQL entities. Each entity can either be a
simple table name (keyword or symbol) or a pair of a
table name and an alias.
> Note: the actual formatting of a `:returning` clause is currently identical to the formatting of a `:select` clause.