2021-11-27 06:06:16 +00:00
# Honey SQL [](https://github.com/seancorfield/honeysql/actions/workflows/test.yml) [](https://gitpod.io/#https://github.com/seancorfield/honeysql)
2012-07-13 01:50:13 +00:00
2013-08-06 20:36:56 +00:00
SQL as Clojure data structures. Build queries programmatically -- even at runtime -- without having to bash strings together.
2012-12-03 17:38:48 +00:00
2015-02-24 06:00:47 +00:00
## Build
2023-02-02 18:35:23 +00:00
[](https://clojars.org/com.github.seancorfield/honeysql) [](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT)
2020-03-08 22:17:18 +00:00
2021-09-26 00:51:48 +00:00
This project follows the version scheme MAJOR.MINOR.COMMITS where MAJOR and MINOR provide some relative indication of the size of the change, but do not follow semantic versioning. In general, all changes endeavor to be non-breaking (by moving to new names rather than by breaking existing names). COMMITS is an ever-increasing counter of commits since the beginning of this repository.
2021-09-26 01:47:18 +00:00
> Note: every commit to the **develop** branch runs CI (GitHub Actions) and successful runs push a MAJOR.MINOR.999-SNAPSHOT build to Clojars so the very latest version of HoneySQL is always available either via that [snapshot on Clojars](https://clojars.org/com.github.seancorfield/honeysql) or via a git dependency on the latest SHA.
2020-05-29 23:10:16 +00:00
2021-03-07 17:43:03 +00:00
HoneySQL 2.x requires Clojure 1.9 or later.
2021-04-30 05:30:28 +00:00
2021-04-11 18:09:47 +00:00
Compared to 1.x, HoneySQL 2.x provides a streamlined codebase and a simpler method for extending the DSL. It also supports SQL dialects out-of-the-box and will be extended to support vendor-specific language features over time (unlike 1.x).
2020-09-25 02:07:32 +00:00
2021-04-11 18:09:47 +00:00
> Note: you can use 1.x and 2.x side-by-side as they use different group IDs and different namespaces. This allows for a piecemeal migration. See this [summary of differences between 1.x and 2.x](doc/differences-from-1-x.md) if you are migrating from 1.x!
2020-03-08 22:17:18 +00:00
2021-08-06 18:35:53 +00:00
## Try HoneySQL Online!
[John Shaffer ](https://github.com/john-shaffer ) has created this awesome
2021-12-04 23:36:03 +00:00
[HoneySQL web app ](https://john.shaffe.rs/honeysql/ ), written in ClojureScript,
2021-08-06 18:35:53 +00:00
so you can experiment with HoneySQL in a browser, including setting different
options so you can generate pretty SQL with inline values (via `:inline true` )
for copying and pasting directly into your SQL tool of choice!
2017-07-19 05:11:49 +00:00
## Note on code samples
2021-08-27 22:16:18 +00:00
Sample code in this documentation is verified via
[lread/test-doc-blocks ](https://github.com/lread/test-doc-blocks ).
2017-07-19 05:11:49 +00:00
2021-02-01 21:10:57 +00:00
Some of these samples show pretty-printed SQL: HoneySQL 2.x supports `:pretty true` which inserts newlines between clauses in the generated SQL strings.
2017-07-19 05:11:49 +00:00
2021-05-20 18:54:52 +00:00
### HoneySQL 1.x
2021-05-20 19:05:32 +00:00
[](https://clojars.org/honeysql/honeysql) [](https://cljdoc.org/d/honeysql/honeysql/CURRENT)
2021-05-20 18:54:52 +00:00
HoneySQL 1.x will continue to get critical security fixes but otherwise should be considered "legacy" at this point.
2012-07-13 01:50:13 +00:00
## Usage
2022-01-20 21:02:17 +00:00
This section includes a number of usage examples but does not dive deep into the
way the data structure acts as a DSL that can specify SQL statements (as hash maps)
and SQL expressions and function calls (as vectors). It is recommended that you read the
[**Getting Started** ](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/doc/getting-started )
section of the documentation before trying to use HoneySQL to build your own queries!
2021-08-27 22:16:18 +00:00
From Clojure:
<!-- {:test - doc - blocks/reader - cond :clj} -->
2017-07-19 05:11:49 +00:00
```clojure
2021-04-11 21:32:48 +00:00
(refer-clojure :exclude '[filter for group-by into partition-by set update])
2020-09-25 02:07:32 +00:00
(require '[honey.sql :as sql]
2021-04-11 21:32:48 +00:00
;; CAUTION: this overwrites several clojure.core fns:
;;
;; filter, for, group-by, into, partition-by, set, and update
;;
2021-03-13 21:46:47 +00:00
;; you should generally only refer in the specific
;; helpers that you want to use!
'[honey.sql.helpers :refer :all :as h]
;; so we can still get at clojure.core functions:
'[clojure.core :as c])
2012-07-13 15:46:50 +00:00
```
2021-08-27 22:16:18 +00:00
From ClojureScript, we don't have `:refer :all` . If we want to use `:refer` , we have no choice but to be specific:
<!-- {:test - doc - blocks/reader - cond :cljs} -->
```Clojure
2021-08-30 21:40:25 +00:00
(refer-clojure :exclude '[filter for group-by into partition-by set update])
2021-08-27 22:16:18 +00:00
(require '[honey.sql :as sql]
'[honey.sql.helpers :refer [select select-distinct from
join left-join right-join
where for group-by having union
order-by limit offset values columns
2021-08-30 21:40:25 +00:00
update insert-into set composite
2021-08-27 22:16:18 +00:00
delete delete-from truncate] :as h]
'[clojure.core :as c])
```
2012-07-13 15:46:50 +00:00
Everything is built on top of maps representing SQL queries:
2012-07-13 13:57:47 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2012-07-13 13:57:47 +00:00
(def sqlmap {:select [:a :b :c]
2019-09-08 06:42:38 +00:00
:from [:foo]
2022-04-23 23:24:04 +00:00
:where [:= :foo.a "baz"]})
2012-07-13 15:46:50 +00:00
```
2019-09-07 20:14:36 +00:00
Column names can be provided as keywords or symbols (but not strings -- HoneySQL treats strings as values that should be lifted out of the SQL as parameters).
2020-02-07 21:49:32 +00:00
### `format`
2020-03-08 22:40:08 +00:00
`format` turns maps into `next.jdbc` -compatible (and `clojure.java.jdbc` -compatible), parameterized SQL:
2012-07-13 13:57:47 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2012-07-13 14:53:19 +00:00
(sql/format sqlmap)
2022-04-23 23:24:04 +00:00
=> ["SELECT a, b, c FROM foo WHERE foo.a = ?" "baz"]
2021-03-08 01:07:38 +00:00
;; sqlmap as symbols instead of keywords:
2022-04-23 23:24:04 +00:00
(-> '{select (a, b, c) from (foo) where (= foo.a "baz")}
2021-03-08 01:07:38 +00:00
(sql/format))
2022-04-23 23:24:04 +00:00
=> ["SELECT a, b, c FROM foo WHERE foo.a = ?" "baz"]
2012-07-13 15:46:50 +00:00
```
2012-07-13 13:57:47 +00:00
2021-07-18 23:36:11 +00:00
HoneySQL is a relatively "pure" library, it does not manage your JDBC connection
2017-05-21 04:45:20 +00:00
or run queries for you, it simply generates SQL strings. You can then pass them
2020-09-25 03:49:22 +00:00
to a JDBC library, such as [`next.jdbc` ](https://github.com/seancorfield/next-jdbc ):
2020-12-15 12:21:07 +00:00
2021-08-27 22:16:18 +00:00
<!-- :test - doc - blocks/skip -->
```clojure
2020-09-25 03:49:22 +00:00
(jdbc/execute! conn (sql/format sqlmap))
2020-12-15 12:21:07 +00:00
```
2021-04-11 18:39:06 +00:00
> Note: you'll need to add your preferred JDBC library as a dependency in your project -- HoneySQL deliberately does not make that choice for you.
2020-12-15 18:16:38 +00:00
2020-12-15 18:12:39 +00:00
If you want to format the query as a string with no parameters (e.g. to use the SQL statement in a SQL console), pass `:inline true` as an option to `sql/format` :
2012-08-24 22:20:58 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2020-12-15 18:12:39 +00:00
(sql/format sqlmap {:inline true})
2022-04-23 23:24:04 +00:00
=> ["SELECT a, b, c FROM foo WHERE foo.a = 'baz'"]
2012-08-24 22:20:58 +00:00
```
2022-12-18 00:18:19 +00:00
As seen above, the default parameterization uses positional parameters (`?`) with the order of values in the generated vector matching the order of those placeholders in the SQL. As of 2.4.962, you can specified `:numbered true` as an option to produce numbered parameters (`$1`, `$2` , etc):
2022-12-18 00:02:02 +00:00
```clojure
(sql/format sqlmap {:numbered true})
=> ["SELECT a, b, c FROM foo WHERE foo.a = $1" "baz"]
```
2021-04-11 18:39:06 +00:00
Namespace-qualified keywords (and symbols) are generally treated as table-qualified columns: `:foo/bar` becomes `foo.bar` , except in contexts where that would be illegal (such as the list of columns in an `INSERT` statement). This approach is likely to be more compatible with code that uses libraries like [`next.jdbc` ](https://github.com/seancorfield/next-jdbc ) and [`seql` ](https://github.com/exoscale/seql ), as well as being more convenient in a world of namespace-qualified keywords, following the example of `clojure.spec` etc.
2012-08-24 22:20:58 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2019-09-08 06:42:38 +00:00
(def q-sqlmap {:select [:foo/a :foo/b :foo/c]
:from [:foo]
:where [:= :foo/a "baz"]})
2020-09-25 02:07:32 +00:00
(sql/format q-sqlmap)
2019-09-08 06:42:38 +00:00
=> ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"]
2021-03-08 01:07:38 +00:00
;; this also works with symbols instead of keywords:
(-> '{select (foo/a, foo/b, foo/c)
from (foo)
where (= foo/a "baz")}
(sql/format))
=> ["SELECT foo.a, foo.b, foo.c FROM foo WHERE foo.a = ?" "baz"]
2012-08-24 22:20:58 +00:00
```
2021-04-11 18:39:06 +00:00
Documentation for the entire data DSL can be found in the
[Clause Reference ](doc/clause-reference.md ), the
2021-08-13 01:34:18 +00:00
[Operator Reference ](doc/operator-reference.md ), and the
[Special Syntax reference ](doc/special-syntax.md ).
2021-04-11 18:39:06 +00:00
2020-02-07 21:49:32 +00:00
### Vanilla SQL clause helpers
2021-03-08 01:07:38 +00:00
For every single SQL clause supported by HoneySQL (as keywords or symbols
in the data structure that is the DSL), there is also a corresponding
function in the `honey.sql.helpers` namespace:
2012-07-13 13:57:47 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2012-07-13 15:46:50 +00:00
(-> (select :a :b :c)
(from :foo)
2022-04-23 23:24:04 +00:00
(where [:= :foo.a "baz"]))
=> {:select [:a :b :c] :from [:foo] :where [:= :foo.a "baz"]}
2012-07-13 15:46:50 +00:00
```
2020-09-25 03:49:22 +00:00
Order doesn't matter (for independent clauses):
2012-07-13 15:46:50 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2012-07-13 15:46:50 +00:00
(= (-> (select :*) (from :foo))
(-> (from :foo) (select :*)))
2012-07-13 14:53:19 +00:00
=> true
2012-07-13 15:46:50 +00:00
```
2012-07-13 14:53:19 +00:00
2021-02-01 22:49:17 +00:00
When using the vanilla helper functions, repeated clauses will be merged into existing clauses, in the natural evaluation order (where that makes sense):
2012-07-13 13:57:47 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2020-09-25 03:49:22 +00:00
(-> sqlmap (select :d))
2022-04-23 23:24:04 +00:00
=> {:from [:foo], :where [:= :foo.a "baz"], :select [:a :b :c :d]}
2012-07-13 15:46:50 +00:00
```
2020-09-25 03:49:22 +00:00
If you want to replace a clause, you can `dissoc` the existing clause first, since this is all data:
2012-07-13 15:46:50 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2012-08-24 22:20:58 +00:00
(-> sqlmap
2020-09-25 03:49:22 +00:00
(dissoc :select)
(select :*)
(where [:> :b 10])
2012-08-24 22:20:58 +00:00
sql/format)
2022-04-23 23:24:04 +00:00
=> ["SELECT * FROM foo WHERE (foo.a = ?) AND (b > ?)" "baz" 10]
2012-07-13 15:46:50 +00:00
```
2012-07-13 13:57:47 +00:00
2021-04-11 18:39:06 +00:00
> Note: the helpers always produce keywords so you can rely on `dissoc` with the desired keyword to remove. If you are building the data DSL "manually" and using symbols instead of keywords, you'll need to `dissoc` the symbol form instead.
2020-02-07 18:31:57 +00:00
`where` will combine multiple clauses together using SQL's `AND` :
2015-03-25 00:31:07 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2015-03-25 00:31:07 +00:00
(-> (select :*)
(from :foo)
(where [:= :a 1] [:< :b 100 ] )
sql/format)
2020-09-25 03:49:22 +00:00
=> ["SELECT * FROM foo WHERE (a = ?) AND (b < ?)" 1 100]
2015-03-25 00:31:07 +00:00
```
2018-06-25 20:00:42 +00:00
Column and table names may be aliased by using a vector pair of the original
name and the desired alias:
```clojure
(-> (select :a [:b :bar] :c [:d :x])
(from [:foo :quux])
(where [:= :quux.a 1] [:< :bar 100 ] )
sql/format)
2020-10-10 06:59:43 +00:00
=> ["SELECT a, b AS bar, c, d AS x FROM foo AS quux WHERE (quux.a = ?) AND (bar < ?)" 1 100]
2018-06-25 20:00:42 +00:00
```
In particular, note that `(select [:a :b])` means `SELECT a AS b` rather than
2021-02-01 22:49:17 +00:00
`SELECT a, b` -- helpers like `select` are generally variadic and do not take
a collection of column names.
2018-06-25 20:00:42 +00:00
2021-03-08 01:07:38 +00:00
The examples in this README use a mixture of data structures and the helper
functions interchangably. For any example using the helpers, you could evaluate
it (without the call to `sql/format` ) to see what the equivalent data structure
would be.
2021-04-11 18:39:06 +00:00
Documentation for all the helpers can be found in the
[`honey.sql.helpers` API reference ](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/api/honey.sql.helpers ).
2018-06-25 20:00:42 +00:00
2020-02-07 21:49:32 +00:00
### Inserts
2018-06-25 19:30:48 +00:00
Inserts are supported in two patterns.
2014-10-07 22:07:39 +00:00
In the first pattern, you must explicitly specify the columns to insert,
then provide a collection of rows, each a collection of column values:
2014-06-21 12:23:02 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2014-06-21 12:23:02 +00:00
(-> (insert-into :properties)
2014-06-21 14:14:46 +00:00
(columns :name :surname :age)
2014-06-21 12:23:02 +00:00
(values
2014-06-21 14:14:46 +00:00
[["Jon" "Smith" 34]
["Andrew" "Cooper" 12]
["Jane" "Daniels" 56]])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true}))
2020-09-26 06:58:51 +00:00
=> ["
2020-10-10 06:59:43 +00:00
INSERT INTO properties
(name, surname, age)
2020-09-26 06:58:51 +00:00
VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
"
"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:insert-into [:properties]
:columns [:name :surname :age]
:values [["Jon" "Smith" 34]
["Andrew" "Cooper" 12]
["Jane" "Daniels" 56]]}
(sql/format {:pretty true}))
=> ["
INSERT INTO properties
(name, surname, age)
VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
"
"Jon" "Smith" 34 "Andrew" "Cooper" 12 "Jane" "Daniels" 56]
2014-06-21 12:23:02 +00:00
```
2021-02-01 22:49:17 +00:00
If the rows are of unequal lengths, they will be padded with `NULL` values to make them consistent.
2014-10-07 22:07:39 +00:00
2021-02-01 22:49:17 +00:00
Alternately, you can simply specify the values as maps:
2014-10-07 22:07:39 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2014-10-07 22:07:39 +00:00
(-> (insert-into :properties)
(values [{:name "John" :surname "Smith" :age 34}
{:name "Andrew" :surname "Cooper" :age 12}
2015-03-17 16:22:05 +00:00
{:name "Jane" :surname "Daniels" :age 56}])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true}))
2020-09-26 06:58:51 +00:00
=> ["
2020-10-10 06:59:43 +00:00
INSERT INTO properties
(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
2020-09-26 06:58:51 +00:00
"
"John" "Smith" 34
"Andrew" "Cooper" 12
"Jane" "Daniels" 56]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:insert-into [:properties]
:values [{:name "John", :surname "Smith", :age 34}
{:name "Andrew", :surname "Cooper", :age 12}
{:name "Jane", :surname "Daniels", :age 56}]}
(sql/format {:pretty true}))
=> ["
INSERT INTO properties
(name, surname, age) VALUES (?, ?, ?), (?, ?, ?), (?, ?, ?)
"
"John" "Smith" 34
"Andrew" "Cooper" 12
"Jane" "Daniels" 56]
2014-10-07 22:07:39 +00:00
```
2021-02-01 22:49:17 +00:00
The set of columns used in the insert will be the union of all column names from all
2021-10-04 23:09:28 +00:00
the hash maps: columns that are missing from any rows will have `NULL` as their value
unless you specify those columns in the `:values-default-columns` option, which takes
a set of column names that should get the value `DEFAULT` instead of `NULL` :
```clojure
(-> (insert-into :properties)
(values [{:name "John" :surname "Smith" :age 34}
{:name "Andrew" :age 12}
{:name "Jane" :surname "Daniels"}])
(sql/format {:pretty true}))
=> ["
INSERT INTO properties
(name, surname, age) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, NULL)
"
"John" "Smith" 34
"Andrew" 12
"Jane" "Daniels"]
(-> (insert-into :properties)
(values [{:name "John" :surname "Smith" :age 34}
{:name "Andrew" :age 12}
{:name "Jane" :surname "Daniels"}])
(sql/format {:pretty true :values-default-columns #{:age}}))
=> ["
INSERT INTO properties
(name, surname, age) VALUES (?, ?, ?), (?, NULL, ?), (?, ?, DEFAULT)
"
"John" "Smith" 34
"Andrew" 12
"Jane" "Daniels"]
```
2014-10-07 22:07:39 +00:00
2020-02-07 21:49:32 +00:00
### Nested subqueries
2014-10-07 22:07:39 +00:00
The column values do not have to be literals, they can be nested queries:
2017-07-19 05:11:49 +00:00
```clojure
2014-10-07 22:07:39 +00:00
(let [user-id 12345
2014-10-22 17:01:46 +00:00
role-name "user"]
2014-10-07 22:07:39 +00:00
(-> (insert-into :user_profile_to_role)
(values [{:user_profile_id user-id
:role_id (-> (select :id)
(from :role)
2014-10-22 17:01:46 +00:00
(where [:= :name role-name]))}])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true})))
2014-10-22 17:01:46 +00:00
2020-09-26 06:58:51 +00:00
=> ["
2020-10-10 06:59:43 +00:00
INSERT INTO user_profile_to_role
(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?))
2020-09-26 06:58:51 +00:00
"
12345
"user"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(let [user-id 12345
role-name "user"]
(-> {:insert-into [:user_profile_to_role]
:values [{:user_profile_id 12345,
:role_id {:select [:id],
:from [:role],
:where [:= :name "user"]}}]}
(sql/format {:pretty true})))
=> ["
INSERT INTO user_profile_to_role
(user_profile_id, role_id) VALUES (?, (SELECT id FROM role WHERE name = ?))
"
12345
"user"]
2014-10-07 22:07:39 +00:00
```
2020-02-07 21:49:32 +00:00
```clojure
(-> (select :*)
(from :foo)
(where [:in :foo.a (-> (select :a) (from :bar))])
2021-03-08 01:07:38 +00:00
(sql/format))
=> ["SELECT * FROM foo WHERE foo.a IN (SELECT a FROM bar)"]
;; or as pure data DSL:
(-> {:select [:*],
:from [:foo],
:where [:in :foo.a {:select [:a], :from [:bar]}]}
(sql/format))
2020-10-10 06:59:43 +00:00
=> ["SELECT * FROM foo WHERE foo.a IN (SELECT a FROM bar)"]
2020-02-07 21:49:32 +00:00
```
2021-07-18 23:36:11 +00:00
Because values can be nested queries -- and also because values can be function calls --
whenever you are working with values that are, themselves, structured data, you will
need to tell HoneySQL not to interpret that structured data as part of the DSL. This
especially affects using JSON values with HoneySQL (e.g., targeting PostgreSQL). There
are two possible approaches:
1. Use named parameters instead of having the values directly in the DSL structure (see `:param` under **Miscellaneous** below), or
2. Use `[:lift ..]` wrapped around any structured values which tells HoneySQL not to interpret the vector or hash map value as a DSL.
2020-02-07 21:49:32 +00:00
### Composite types
2019-09-07 22:56:06 +00:00
Composite types are supported:
```clojure
(-> (insert-into :comp_table)
(columns :name :comp_column)
(values
[["small" (composite 1 "inch")]
["large" (composite 10 "feet")]])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true}))
2020-09-26 06:58:51 +00:00
=> ["
2020-10-10 06:59:43 +00:00
INSERT INTO comp_table
(name, comp_column)
2020-09-26 06:58:51 +00:00
VALUES (?, (?, ?)), (?, (?, ?))
"
"small" 1 "inch" "large" 10 "feet"]
2022-12-18 00:02:02 +00:00
;; with numbered parameters:
(-> (insert-into :comp_table)
(columns :name :comp_column)
(values
[["small" (composite 1 "inch")]
["large" (composite 10 "feet")]])
(sql/format {:pretty true :numbered true}))
=> ["
INSERT INTO comp_table
(name, comp_column)
VALUES ($1, ($2, $3)), ($4, ($5, $6))
"
"small" 1 "inch" "large" 10 "feet"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:insert-into [:comp_table],
:columns [:name :comp_column],
:values [["small" [:composite 1 "inch"]]
["large" [:composite 10 "feet"]]]}
(sql/format {:pretty true}))
=> ["
INSERT INTO comp_table
(name, comp_column)
VALUES (?, (?, ?)), (?, (?, ?))
"
"small" 1 "inch" "large" 10 "feet"]
2019-09-07 22:56:06 +00:00
```
2020-02-07 21:49:32 +00:00
### Updates
2020-09-29 02:24:17 +00:00
Updates are possible too:
2014-06-21 12:23:02 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2021-08-30 21:40:25 +00:00
(-> (update :films)
2020-09-29 02:24:17 +00:00
(set {:kind "dramatic"
:watched [:+ :watched 1]})
2014-06-21 14:14:46 +00:00
(where [:= :kind "drama"])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true}))
2020-09-26 06:58:51 +00:00
=> ["
2020-10-10 06:59:43 +00:00
UPDATE films
SET kind = ?, watched = watched + ?
2020-09-26 06:58:51 +00:00
WHERE kind = ?
"
"dramatic"
1
"drama"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:update :films,
:set {:kind "dramatic", :watched [:+ :watched 1]},
:where [:= :kind "drama"]}
(sql/format {:pretty true}))
=> ["
UPDATE films
SET kind = ?, watched = watched + ?
WHERE kind = ?
"
"dramatic"
1
"drama"]
2014-06-21 12:23:02 +00:00
```
2019-09-07 21:55:06 +00:00
If you are trying to build a compound update statement (with `from` or `join` ),
be aware that different databases have slightly different syntax in terms of
2020-09-25 03:49:22 +00:00
where `SET` should appear. The default above is to put `SET` before `FROM` which
is how PostgreSQL (and other ANSI-SQL dialects work). If you are using MySQL,
you will need to select the `:mysql` dialect in order to put the `SET` after
any `JOIN` clause.
2019-09-07 21:55:06 +00:00
2020-02-07 21:49:32 +00:00
### Deletes
2014-06-21 12:23:02 +00:00
Deletes look as you would expect:
2017-07-19 05:11:49 +00:00
```clojure
2014-06-21 14:14:46 +00:00
(-> (delete-from :films)
(where [:< > :kind "musical"])
2020-09-26 06:58:51 +00:00
(sql/format))
2014-06-21 12:23:02 +00:00
=> ["DELETE FROM films WHERE kind < > ?" "musical"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:delete-from [:films],
:where [:< > :kind "musical"]}
(sql/format))
2014-06-21 12:23:02 +00:00
=> ["DELETE FROM films WHERE kind < > ?" "musical"]
```
2018-06-27 01:24:01 +00:00
If your database supports it, you can also delete from multiple tables:
```clojure
(-> (delete [:films :directors])
(from :films)
(join :directors [:= :films.director_id :directors.id])
(where [:< > :kind "musical"])
2021-02-01 21:10:57 +00:00
(sql/format {:pretty true}))
2020-09-26 06:58:51 +00:00
=> ["
DELETE films, directors
FROM films
INNER JOIN directors ON films.director_id = directors.id
WHERE kind < > ?
"
"musical"]
2021-03-08 01:07:38 +00:00
;; or pure data DSL:
(-> {:delete [:films :directors],
:from [:films],
:join [:directors [:= :films.director_id :directors.id]],
:where [:< > :kind "musical"]}
(sql/format {:pretty true}))
=> ["
DELETE films, directors
FROM films
INNER JOIN directors ON films.director_id = directors.id
WHERE kind < > ?
"
"musical"]
2018-06-27 01:24:01 +00:00
```
2019-09-07 20:24:46 +00:00
If you want to delete everything from a table, you can use `truncate` :
```clojure
(-> (truncate :films)
2020-09-26 06:58:51 +00:00
(sql/format))
2019-09-07 20:24:46 +00:00
=> ["TRUNCATE films"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:truncate :films}
(sql/format))
2019-09-07 20:24:46 +00:00
=> ["TRUNCATE films"]
```
2020-03-06 17:34:06 +00:00
### Set operations
2012-07-13 13:57:47 +00:00
2021-02-01 22:49:17 +00:00
Queries may be combined with a `:union` , `:union-all` , `:intersect` or `:except` keyword:
2015-08-25 15:25:05 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2015-08-25 15:25:05 +00:00
(sql/format {:union [(-> (select :*) (from :foo))
(-> (select :*) (from :bar))]})
2021-10-04 05:18:12 +00:00
=> ["SELECT * FROM foo UNION SELECT * FROM bar"]
2015-08-25 15:25:05 +00:00
```
2021-02-01 22:49:17 +00:00
There are also helpers for each of those:
```clojure
(sql/format (union (-> (select :*) (from :foo))
(-> (select :*) (from :bar))))
2021-10-04 05:18:12 +00:00
=> ["SELECT * FROM foo UNION SELECT * FROM bar"]
2015-08-25 15:25:05 +00:00
```
2020-02-07 21:49:32 +00:00
### Functions
2022-01-20 21:02:17 +00:00
Function calls (and expressions with operators) can be specified as
vectors where the first element is either a keyword or a symbol:
```clojure
(-> (select :*) (from :foo)
(where [:> :date_created [:date_add [:now] [:interval 24 :hours]]])
(sql/format))
=> ["SELECT * FROM foo WHERE date_created > DATE_ADD(NOW(), INTERVAL ? HOURS)" 24]
```
2022-09-02 05:23:33 +00:00
> Note: The above example may be specific to MySQL but the general principle of vectors for function calls applies to all dialects.
2022-01-20 21:02:17 +00:00
A shorthand syntax also exists for simple function calls:
keywords that begin with `%` are interpreted as SQL function calls:
2012-07-13 15:46:50 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2013-08-06 18:05:17 +00:00
(-> (select :%count.*) (from :foo) sql/format)
2021-02-01 22:49:17 +00:00
=> ["SELECT COUNT(*) FROM foo"]
2020-03-03 07:20:08 +00:00
```
```clojure
2014-07-25 05:52:08 +00:00
(-> (select :%max.id) (from :foo) sql/format)
2021-02-01 22:49:17 +00:00
=> ["SELECT MAX(id) FROM foo"]
2013-08-06 18:05:17 +00:00
```
2021-02-01 22:49:17 +00:00
Since regular function calls are indicated with vectors and so are aliased pairs,
this shorthand can be more convenient due to the extra wrapping needed for the
regular function calls in a select:
2020-02-07 21:49:32 +00:00
2021-02-01 22:49:17 +00:00
```clojure
(-> (select [[:count :*]]) (from :foo) sql/format)
=> ["SELECT COUNT(*) FROM foo"]
```
```clojure
2022-01-20 21:02:17 +00:00
(-> (select [:%count.*]) (from :foo) sql/format)
=> ["SELECT COUNT(*) FROM foo"]
;; or even:
(-> (select :%count.*) (from :foo) sql/format)
=> ["SELECT COUNT(*) FROM foo"]
```
```clojure
2021-02-01 22:49:17 +00:00
(-> (select [[:max :id]]) (from :foo) sql/format)
=> ["SELECT MAX(id) FROM foo"]
2021-03-08 01:07:38 +00:00
;; the pure data DSL requires an extra level of brackets:
(-> {:select [[[:max :id]]], :from [:foo]} sql/format)
=> ["SELECT MAX(id) FROM foo"]
2022-01-20 21:02:17 +00:00
;; the shorthand makes this simpler:
(-> {:select [[:%max.id]], :from [:foo]} sql/format)
=> ["SELECT MAX(id) FROM foo"]
;; or even:
(-> {:select [:%max.id], :from [:foo]} sql/format)
=> ["SELECT MAX(id) FROM foo"]
;; or even:
(-> {:select :%max.id, :from :foo} sql/format)
=> ["SELECT MAX(id) FROM foo"]
2013-08-06 18:05:17 +00:00
```
2022-02-03 07:51:01 +00:00
If a keyword begins with `'` , the function name is formatted as a SQL
entity rather than being converted to uppercase and having hyphens `-`
converted to spaces). That means that hyphens `-` will become underscores `_`
unless you have quoting enabled:
2022-02-03 06:34:21 +00:00
```clojure
(-> (select :*) (from :foo)
(where [:'my-schema.SomeFunction :bar 0])
(sql/format))
2022-02-03 07:51:01 +00:00
=> ["SELECT * FROM foo WHERE my_schema.SomeFunction(bar, ?)" 0]
(-> (select :*) (from :foo)
(where [:'my-schema.SomeFunction :bar 0])
(sql/format :quoted true))
=> ["SELECT * FROM \"foo\" WHERE \"my-schema\".\"SomeFunction\"(\"bar\", ?)" 0]
(-> (select :*) (from :foo)
(where [:'my-schema.SomeFunction :bar 0])
(sql/format :dialect :mysql))
=> ["SELECT * FROM `foo` WHERE `my-schema` .`SomeFunction`(`bar`, ?)" 0]
2022-02-03 06:34:21 +00:00
```
2022-09-12 19:45:50 +00:00
> Note: in non-function contexts, if a keyword begins with `'`, it is transcribed into the SQL exactly as-is, with no case or character conversion at all.
2020-02-07 21:49:32 +00:00
### Bindable parameters
2013-08-06 18:27:56 +00:00
Keywords that begin with `?` are interpreted as bindable parameters:
2017-07-19 05:11:49 +00:00
```clojure
2013-08-06 18:27:56 +00:00
(-> (select :id)
(from :foo)
(where [:= :a :?baz])
2020-10-02 06:30:18 +00:00
(sql/format {:params {:baz "BAZ"}}))
2020-10-10 06:59:43 +00:00
=> ["SELECT id FROM foo WHERE a = ?" "BAZ"]
2022-12-18 00:02:02 +00:00
;; or with numbered parameters:
(-> (select :id)
(from :foo)
(where [:= :a :?baz])
(sql/format {:params {:baz "BAZ"} :numbered true}))
=> ["SELECT id FROM foo WHERE a = $1" "BAZ"]
2021-03-08 01:07:38 +00:00
;; or as pure data DSL:
(-> {:select [:id], :from [:foo], :where [:= :a :?baz]}
(sql/format {:params {:baz "BAZ"}}))
2013-08-06 18:27:56 +00:00
=> ["SELECT id FROM foo WHERE a = ?" "BAZ"]
```
2020-02-07 21:49:32 +00:00
### Miscellaneous
2021-02-01 22:49:17 +00:00
Sometimes you want to provide SQL fragments directly or have certain values
placed into the SQL string rather than turned into a parameter.
The `:raw` syntax lets you embed SQL fragments directly into a HoneySQL expression.
It accepts either a single string to embed or a vector of expressions that will be
converted to strings and embedded as a single string.
The `:inline` syntax attempts to turn a Clojure value into a SQL value and then
embeds that string, e.g., `[:inline "foo"]` produces `'foo'` (a SQL string).
The `:param` syntax identifies a named parameter whose value will be supplied
via the `:params` argument to `format` .
The `:lift` syntax will prevent interpretation of Clojure data structures as
part of the DSL and instead turn such values into parameters (useful when you
want to pass a vector or a hash map directly as a positional parameter value,
for example when you have extended `next.jdbc` 's `SettableParameter` protocol
2021-08-13 01:34:18 +00:00
to a data structure -- as is common when working with PostgreSQL's JSON/JSONB types).
2021-02-01 22:49:17 +00:00
Finally, the `:nest` syntax will cause an extra set of parentheses to be
wrapped around its argument, after formatting that argument as a SQL expression.
These can be combined to allow more fine-grained control over SQL generation:
2013-08-06 18:05:17 +00:00
2017-07-19 05:11:49 +00:00
```clojure
(def call-qualify-map
2020-09-25 03:49:22 +00:00
(-> (select [[:foo :bar]] [[:raw "@var := foo.bar"]])
2017-07-19 05:11:49 +00:00
(from :foo)
2020-09-29 02:24:17 +00:00
(where [:= :a [:param :baz]] [:= :b [:inline 42]])))
2020-03-03 07:20:08 +00:00
```
```clojure
2017-07-19 05:11:49 +00:00
call-qualify-map
2021-08-27 22:16:18 +00:00
=> {:where [:and [:= :a [:param :baz]] [:= :b [:inline 42]]]
:from (:foo)
:select [[[:foo :bar]] [[:raw "@var := foo.bar"]]]}
2020-03-03 07:20:08 +00:00
```
```clojure
2020-09-29 02:24:17 +00:00
(sql/format call-qualify-map {:params {:baz "BAZ"}})
2020-10-10 06:59:43 +00:00
=> ["SELECT FOO(bar), @var := foo.bar FROM foo WHERE (a = ?) AND (b = 42)" "BAZ"]
2012-07-13 13:57:47 +00:00
```
2012-07-13 01:50:13 +00:00
2019-10-19 19:12:23 +00:00
```clojure
2018-06-30 04:59:17 +00:00
(-> (select :*)
(from :foo)
2020-09-29 02:24:17 +00:00
(where [:< :expired_at [ :raw [ " now ( ) - ' " 5 " seconds ' " ] ] ] )
2019-10-19 19:12:23 +00:00
(sql/format))
2021-01-30 20:35:51 +00:00
=> ["SELECT * FROM foo WHERE expired_at < now ( ) - ' 5 seconds ' " ]
2019-10-19 19:12:23 +00:00
```
2018-06-30 04:59:17 +00:00
```clojure
(-> (select :*)
(from :foo)
2021-01-30 20:42:08 +00:00
(where [:< :expired_at [ :raw [ " now ( ) - ' " [ :lift 5 ] " seconds ' " ] ] ] )
(sql/format))
2018-06-30 04:59:17 +00:00
=> ["SELECT * FROM foo WHERE expired_at < now ( ) - ' ? seconds ' " 5 ]
```
```clojure
(-> (select :*)
(from :foo)
2020-09-29 02:24:17 +00:00
(where [:< :expired_at [ :raw [ " now ( ) - ' " [ :param :t ] " seconds ' " ] ] ] )
2021-01-30 20:35:51 +00:00
(sql/format {:params {:t 5}}))
2018-06-30 04:59:17 +00:00
=> ["SELECT * FROM foo WHERE expired_at < now ( ) - ' ? seconds ' " 5 ]
```
2018-06-25 19:30:48 +00:00
2021-01-30 20:35:51 +00:00
```clojure
(-> (select :*)
(from :foo)
(where [:< :expired_at [ :raw [ " now ( ) - " [ :inline ( str 5 " seconds " ) ] ] ] ] )
(sql/format))
=> ["SELECT * FROM foo WHERE expired_at < now ( ) - ' 5 seconds ' " ]
```
2021-02-01 22:49:17 +00:00
#### PostGIS
A common example in the wild is the PostGIS extension to PostgreSQL where you
have a lot of function calls needed in code:
```clojure
(-> (insert-into :sample)
(values [{:location [:ST_SetSRID
[:ST_MakePoint 0.291 32.621]
[:cast 4325 :integer]]}])
(sql/format {:pretty true}))
=> ["
INSERT INTO sample
2022-11-19 21:51:43 +00:00
(location) VALUES (ST_SETSRID(ST_MAKEPOINT(?, ?), CAST(? AS INTEGER)))
2021-02-01 22:49:17 +00:00
"
0.291 32.621 4325]
```
2022-08-24 00:18:00 +00:00
#### Entity Names
2020-02-07 21:49:32 +00:00
2022-08-24 00:18:00 +00:00
To quote SQL entity names, pass the `:quoted true` option to `format` and they will
2020-09-25 03:49:22 +00:00
be quoted according to the selected dialect. If you override the dialect in a
2022-08-24 00:18:00 +00:00
`format` call, by passing the `:dialect` option, SQL entity names will be automatically
2020-09-25 03:49:22 +00:00
quoted. You can override the dialect and turn off quoting by passing `:quoted false` .
Valid `:dialect` options are `:ansi` (the default, use this for PostgreSQL),
`:mysql` , `:oracle` , or `:sqlserver` :
2013-08-06 19:08:09 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2013-08-06 19:08:09 +00:00
(-> (select :foo.a)
(from :foo)
(where [:= :foo.a "baz"])
2020-09-25 03:49:22 +00:00
(sql/format {:dialect :mysql}))
2013-08-06 19:08:09 +00:00
=> ["SELECT `foo` .`a` FROM `foo` WHERE `foo` .`a` = ?" "baz"]
```
2020-02-07 21:49:32 +00:00
#### Locking
2020-09-29 03:45:43 +00:00
The ANSI/PostgreSQL/SQLServer dialects support locking selects via a `FOR` clause as follows:
2020-09-25 03:49:22 +00:00
2021-02-01 22:49:17 +00:00
* `:for [<lock-strength> <table(s)> <qualifier>]` where `<lock-strength>` is required and may be one of:
2020-09-29 03:45:43 +00:00
* `:update`
* `:no-key-update`
* `:share`
* `:key-share`
2021-02-01 22:49:17 +00:00
* Both `<table(s)>` and `<qualifier>` are optional but if present, `<table(s)>` must either be:
2020-09-29 03:45:43 +00:00
* a single table name (as a keyword) or
* a sequence of table names (as keywords)
2021-02-01 22:49:17 +00:00
* `<qualifier>` can be `:nowait` , `:wait` , `:skip-locked` etc.
2020-09-29 03:45:43 +00:00
2021-02-01 22:49:17 +00:00
If `<table(s)>` and `<qualifier>` are both omitted, you may also omit the `[` ..`]` and just say `:for :update` etc.
2015-04-20 01:57:44 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2015-04-20 01:57:44 +00:00
(-> (select :foo.a)
(from :foo)
2017-07-19 01:01:00 +00:00
(where [:= :foo.a "baz"])
2021-08-30 21:40:25 +00:00
(for :update)
2015-04-20 01:57:44 +00:00
(sql/format))
=> ["SELECT foo.a FROM foo WHERE foo.a = ? FOR UPDATE" "baz"]
```
2020-09-29 03:45:43 +00:00
If the `:mysql` dialect is selected, an additional locking clause is available:
`:lock :in-share-mode` .
```clojure
(sql/format {:select [:*] :from :foo
:where [:= :name [:inline "Jones"]]
:lock [:in-share-mode]}
{:dialect :mysql :quoted false})
=> ["SELECT * FROM foo WHERE name = 'Jones' LOCK IN SHARE MODE"]
```
2015-04-20 01:57:44 +00:00
2021-02-01 22:49:17 +00:00
Dashes are allowed in quoted names:
2015-04-20 01:57:44 +00:00
2017-07-19 05:11:49 +00:00
```clojure
(sql/format
2015-10-16 19:19:42 +00:00
{:select [:f.foo-id :f.foo-name]
:from [[:foo-bar :f]]
:where [:= :f.foo-id 12345]}
2021-02-01 22:49:17 +00:00
{:quoted true})
2020-10-10 06:59:43 +00:00
=> ["SELECT \"f\".\"foo-id\", \"f\".\"foo-name\" FROM \"foo-bar\" AS \"f\" WHERE \"f\".\"foo-id\" = ?" 12345]
2015-10-16 19:19:42 +00:00
```
2020-02-07 21:49:32 +00:00
### Big, complicated example
2021-02-01 22:49:17 +00:00
Here's a big, complicated query. Note that HoneySQL makes no attempt to verify that your queries make any sense. It merely renders surface syntax.
2012-07-13 15:46:50 +00:00
2017-07-19 05:11:49 +00:00
```clojure
(def big-complicated-map
2020-10-10 06:05:05 +00:00
(-> (select-distinct :f.* :b.baz :c.quux [:b.bla "bla-bla"]
[[:now]] [[:raw "@x := 10"]])
2017-07-19 05:11:49 +00:00
(from [:foo :f] [:baz :b])
2021-06-19 02:43:01 +00:00
(join :draq [:= :f.b :draq.x]
:eldr [:= :f.e :eldr.t])
2017-07-19 05:11:49 +00:00
(left-join [:clod :c] [:= :f.a :c.d])
(right-join :bock [:= :bock.z :c.e])
(where [:or
2020-09-29 02:24:17 +00:00
[:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]]
2020-10-10 06:59:43 +00:00
[:and [:< 1 2 ] [ : < 2 3 ] ]
2020-09-29 02:24:17 +00:00
[:in :f.e [1 [:param :param2] 3]]
2017-07-19 05:11:49 +00:00
[:between :f.e 10 20]])
2020-09-29 03:45:43 +00:00
(group-by :f.a :c.e)
2017-07-19 05:11:49 +00:00
(having [:< 0 :f . e ] )
(order-by [:b.baz :desc] :c.quux [:f.a :nulls-first])
(limit 50)
(offset 10)))
2020-03-03 07:20:08 +00:00
```
```clojure
2017-07-19 05:11:49 +00:00
big-complicated-map
2020-10-10 06:05:05 +00:00
=> {:select-distinct [:f.* :b.baz :c.quux [:b.bla "bla-bla"]
[[:now]] [[:raw "@x := 10"]]]
2012-10-19 16:41:26 +00:00
:from [[:foo :f] [:baz :b]]
2021-06-19 02:43:01 +00:00
:join [:draq [:= :f.b :draq.x]
:eldr [:= :f.e :eldr.t]]
2012-10-19 16:41:26 +00:00
:left-join [[:clod :c] [:= :f.a :c.d]]
:right-join [:bock [:= :bock.z :c.e]]
:where [:or
2020-09-29 02:24:17 +00:00
[:and [:= :f.a "bort"] [:not= :b.baz [:param :param1]]]
2020-10-10 06:59:43 +00:00
[:and [:< 1 2 ] [ : < 2 3 ] ]
2020-09-29 02:24:17 +00:00
[:in :f.e [1 [:param :param2] 3]]
2012-10-19 16:41:26 +00:00
[:between :f.e 10 20]]
2020-02-12 20:10:24 +00:00
:group-by [:f.a :c.e]
2012-10-19 16:41:26 +00:00
:having [:< 0 :f . e ]
2017-07-19 01:01:00 +00:00
:order-by [[:b.baz :desc] :c.quux [:f.a :nulls-first]]
2012-10-19 16:41:26 +00:00
:limit 50
:offset 10}
2020-03-03 07:20:08 +00:00
```
```clojure
2020-10-10 06:59:43 +00:00
(sql/format big-complicated-map
{:params {:param1 "gabba" :param2 2}
2021-02-01 21:10:57 +00:00
:pretty true})
2020-09-26 06:58:51 +00:00
=> ["
2021-02-13 23:58:56 +00:00
SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10
2020-10-10 06:59:43 +00:00
FROM foo AS f, baz AS b
2021-06-19 02:43:01 +00:00
INNER JOIN draq ON f.b = draq.x INNER JOIN eldr ON f.e = eldr.t
2020-10-10 06:59:43 +00:00
LEFT JOIN clod AS c ON f.a = c.d
2020-09-26 06:58:51 +00:00
RIGHT JOIN bock ON bock.z = c.e
2020-10-10 06:59:43 +00:00
WHERE ((f.a = ?) AND (b.baz < > ?)) OR ((? < ?) AND (? < ?)) OR (f.e IN (?, ?, ?)) OR f.e BETWEEN ? AND ?
2020-09-26 06:58:51 +00:00
GROUP BY f.a, c.e
HAVING ? < f.e
2020-10-12 18:33:18 +00:00
ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST
2020-09-26 06:58:51 +00:00
LIMIT ?
OFFSET ?
"
"bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]
2022-12-18 00:02:02 +00:00
;; with numbered parameters:
(sql/format big-complicated-map
{:params {:param1 "gabba" :param2 2}
:pretty true :numbered true})
=> ["
SELECT DISTINCT f.*, b.baz, c.quux, b.bla AS \"bla-bla\", NOW(), @x := 10
FROM foo AS f, baz AS b
INNER JOIN draq ON f.b = draq.x INNER JOIN eldr ON f.e = eldr.t
LEFT JOIN clod AS c ON f.a = c.d
RIGHT JOIN bock ON bock.z = c.e
WHERE ((f.a = $1) AND (b.baz < > $2)) OR (($3 < $4) AND ($5 < $6)) OR (f.e IN ($7, $8, $9)) OR f.e BETWEEN $10 AND $11
GROUP BY f.a, c.e
HAVING $12 < f.e
ORDER BY b.baz DESC, c.quux ASC, f.a NULLS FIRST
LIMIT $13
OFFSET $14
"
"bort" "gabba" 1 2 2 3 1 2 3 10 20 0 50 10]
2020-03-03 07:20:08 +00:00
```
```clojure
2012-07-13 17:13:37 +00:00
;; Printable and readable
2021-08-27 22:16:18 +00:00
(require '[clojure.edn :as edn])
(= big-complicated-map (edn/read-string (pr-str big-complicated-map)))
2012-07-13 17:09:02 +00:00
=> true
2012-07-13 15:46:50 +00:00
```
2012-08-24 22:20:58 +00:00
## Extensibility
2021-02-01 22:49:17 +00:00
Any keyword (or symbol) that appears as the first element of a vector will be treated as a generic function unless it is declared to be an operator or "special syntax". Any keyword (or symbol) that appears as a key in a hash map will be treated as a SQL clause -- and must either be built-in or must be registered as a new clause.
2012-08-24 22:20:58 +00:00
2020-10-10 05:31:55 +00:00
If your database supports `<=>` as an operator, you can tell HoneySQL about it using the `register-op!` function (which should be called before the first call to `honey.sql/format` ):
2012-08-24 22:20:58 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2020-10-10 05:31:55 +00:00
(sql/register-op! :< =>)
;; default is a binary operator:
(-> (select :a) (where [:< => :a "foo"]) sql/format)
=> ["SELECT a WHERE a < => ?" "foo"]
;; you can declare that an operator is variadic:
2021-02-02 00:24:19 +00:00
(sql/register-op! :< => :variadic true)
2020-10-10 05:31:55 +00:00
(-> (select :a) (where [:< => "food" :a "fool"]) sql/format)
=> ["SELECT a WHERE ? < => a < => ?" "food" "fool"]
2020-03-03 07:20:08 +00:00
```
2012-08-24 22:37:03 +00:00
2020-10-10 05:31:55 +00:00
Sometimes you want an operator to ignore `nil` clauses (`:and` and `:or` are declared that way):
2012-08-24 22:20:58 +00:00
2017-07-19 05:11:49 +00:00
```clojure
2021-02-02 00:24:19 +00:00
(sql/register-op! :< => :ignore-nil true)
2012-08-24 22:20:58 +00:00
```
2020-10-10 05:31:55 +00:00
Or perhaps your database supports syntax like `a BETWIXT b AND c` , in which case you can use `register-fn!` to tell HoneySQL about it (again, called before the first call to `honey.sql/format` ):
2019-03-25 21:40:00 +00:00
```clojure
2020-10-10 05:31:55 +00:00
;; the formatter will be passed your new operator (function) and a
;; sequence of the arguments provided to it (so you can write any arity ops):
(sql/register-fn! :betwixt
(fn [op [a b c]]
(let [[sql-a & params-a] (sql/format-expr a)
[sql-b & params-b] (sql/format-expr b)
[sql-c & params-c] (sql/format-expr c)]
(-> [(str sql-a " " (sql/sql-kw op) " "
sql-b " AND " sql-c)]
2021-03-13 21:46:47 +00:00
(c/into params-a)
(c/into params-b)
(c/into params-c)))))
2020-10-10 05:31:55 +00:00
;; example usage:
(-> (select :a) (where [:betwixt :a 1 10]) sql/format)
=> ["SELECT a WHERE a BETWIXT ? AND ?" 1 10]
2022-12-18 00:02:02 +00:00
;; with numbered parameters:
(-> (select :a) (where [:betwixt :a 1 10]) (sql/format {:numbered true}))
=> ["SELECT a WHERE a BETWIXT $1 AND $2" 1 10]
2019-03-25 21:40:00 +00:00
```
2022-12-18 00:02:02 +00:00
> Note: the generation of positional placeholders (`?`) or numbered placeholders (`$1`, `$2`, etc) is handled automatically by `format-expr` so you get this behavior "for free" in your extensions, as long as you use the public API for `honey.sql`. You should avoid writing extensions that generate placeholders directly if you want them to work with numbered parameters.
2020-10-10 05:31:55 +00:00
You can also register SQL clauses, specifying the keyword, the formatting function, and an existing clause that this new clause should be processed before:
2017-08-26 18:39:04 +00:00
2019-03-25 21:40:00 +00:00
```clojure
2020-10-10 05:31:55 +00:00
;; the formatter will be passed your new clause and the value associated
;; with that clause in the DSL (which is often a sequence but does not
;; need to be -- it can be whatever syntax you desire in the DSL):
(sql/register-clause! :foobar
(fn [clause x]
(let [[sql & params]
2021-03-07 17:43:03 +00:00
(if (ident? x)
2020-10-10 05:31:55 +00:00
(sql/format-expr x)
(sql/format-dsl x))]
2021-03-13 21:46:47 +00:00
(c/into [(str (sql/sql-kw clause) " " sql)] params)))
2020-10-10 05:31:55 +00:00
:from) ; SELECT ... FOOBAR ... FROM ...
;; example usage:
(sql/format {:select [:a :b] :foobar :baz})
=> ["SELECT a, b FOOBAR baz"]
(sql/format {:select [:a :b] :foobar {:where [:= :id 1]}})
=> ["SELECT a, b FOOBAR WHERE id = ?" 1]
2017-08-26 18:39:04 +00:00
```
2016-07-10 18:43:18 +00:00
2020-10-10 05:31:55 +00:00
If you find yourself registering an operator, a function (syntax), or a new clause, consider submitting a [pull request to HoneySQL ](https://github.com/seancorfield/honeysql/pulls ) so others can use it, too. If it is dialect-specific, let me know in the pull request.
2016-07-10 18:43:18 +00:00
2012-07-13 01:50:13 +00:00
## License
2022-12-18 00:02:02 +00:00
Copyright (c) 2020-2022 Sean Corfield. HoneySQL 1.x was copyright (c) 2012-2020 Justin Kramer and Sean Corfield.
2012-07-13 01:50:13 +00:00
Distributed under the Eclipse Public License, the same as Clojure.