311 lines
11 KiB
Markdown
311 lines
11 KiB
Markdown
# Getting Started with HoneySQL
|
|
|
|
HoneySQL lets you build complex SQL statements by constructing
|
|
and composing Clojure data structures and then formatting that
|
|
data to a SQL statement (string) and any parameters it needs.
|
|
|
|
## Installation
|
|
|
|
For the Clojure CLI, add the following dependency to your `deps.edn` file:
|
|
|
|
```clojure
|
|
seancorfield/honeysql {:mvn/version "2.0.0-alpha1"}
|
|
```
|
|
|
|
For Leiningen, add the following dependency to your `project.clj` file:
|
|
|
|
```clojure
|
|
[seancorfield/honeysql "2.0.0-alpha1"]
|
|
```
|
|
|
|
HoneySQL produces SQL statements but does not execute them.
|
|
To execute SQL statements, you will also need a JDBC wrapper like
|
|
[`seancorfield/next.jdbc`](https://github.com/seancorfield/next-jdbc) and a JDBC driver for the database you use.
|
|
|
|
## Basic Concepts
|
|
|
|
SQL statements are represented as hash maps, with keys that
|
|
represent clauses in SQL. SQL expressions are generally
|
|
represented as vectors, where the first element identifies
|
|
the function or operator and the remaining elements are the
|
|
arguments or operands.
|
|
|
|
`honey.sql/format` takes a hash map representing a SQL
|
|
statement and produces a vector, suitable for use with
|
|
`next.jdbc` or `clojure.java.jdbc`, that has the generated
|
|
SQL string as the first element followed by any parameter
|
|
values identified in the SQL expressions:
|
|
|
|
```clojure
|
|
(ns my.example
|
|
(:require [honey.sql :as sql]))
|
|
|
|
(sql/format {:select [:*], :from [:table], :where [:= :id 1]})
|
|
;; produces:
|
|
;;=> ["SELECT * FROM table WHERE id = ?" 1]
|
|
```
|
|
|
|
By default, any values found in the data structure, that are not keywords
|
|
or symbols, are treated as positional parameters and replaced
|
|
by `?` in the SQL string and lifted out into the vector that
|
|
is returned from `format`.
|
|
|
|
Most clauses expect a vector as their value, containing
|
|
either a list of SQL entities or the representation of a SQL
|
|
expression. Some clauses accept a single SQL entity. A few
|
|
accept a most specialized form (such as `:set` accepting a
|
|
hash map of SQL entities and SQL expressions).
|
|
|
|
A SQL entity can be a simple keyword (or symbol) or a pair
|
|
that represents a SQL entity and its alias (where aliases are allowed):
|
|
|
|
```clojure
|
|
(sql/format {:select [:t.id [:name :item]], :from [[:table :t]], :where [:= :id 1]})
|
|
;; produces:
|
|
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
The `FROM` clause now has a pair that identifies the SQL entity
|
|
`table` and its alias `t`. Columns can be identified either by
|
|
their qualified name (as in `:t.id`) or their unqualified name
|
|
(as in `:name`). The `SELECT` clause here identifies two SQL
|
|
entities: `t.id` and `name` with the latter aliased to `item`.
|
|
|
|
Symbols can also be used, but you need to quote them to
|
|
avoid evaluation:
|
|
|
|
```clojure
|
|
(sql/format '{select [t.id [name item]], from [[table t]], where [= id 1]})
|
|
;; or you can use (..) instead of [..] when quoted:
|
|
(sql/format '{select (t.id (name item)), from ((table t)), where (= id 1)})
|
|
;; also produces:
|
|
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
If you wish, you can specify SQL entities as namespace-qualified
|
|
keywords (or symbols) and the namespace portion will treated as
|
|
the table name, i.e., `:foo/bar` instead of `:foo.bar`:
|
|
|
|
```clojure
|
|
(sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]})
|
|
;; and
|
|
(sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]})
|
|
;; both produce:
|
|
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
## SQL Expressions
|
|
|
|
In addition to using hash maps to describe SQL clauses,
|
|
HoneySQL uses vectors to describe SQL expressions. Any
|
|
sequence that begins with a keyword (or symbol) is considered
|
|
to be a kind of function invocation. Certain "functions" are
|
|
considered to be "special syntax" and have custom rendering.
|
|
Some "functions" are considered to be operators. In general,
|
|
`[:foo :a 42 "c"]` will render as `FOO(a, ?, ?)` with the parameters
|
|
`42` and `"c"` lifted out into the overall vector result
|
|
(with a SQL string followed by all its parameters).
|
|
|
|
Operators can be strictly binary or variadic (most are strictly binary).
|
|
Special syntax can have zero or more arguments and each form is
|
|
described in the [Special Syntax](docs/special-syntax.md) section.
|
|
|
|
Some examples:
|
|
|
|
```clojure
|
|
[:= :a 42] ;=> "a = ?" with a parameter of 42
|
|
[:+ 42 :a :b] ;=> "? + a + b" with a parameter of 42
|
|
[:= :x [:inline "foo"]] ;=> "x = 'foo'" -- the string is inlined
|
|
[:now] ;=> "NOW()"
|
|
[:count :*] ;=> "COUNT(*)"
|
|
[:or [:<> :name nil] [:= :status-id 0]] ;=> "(name IS NOT NULL) OR (status_id = ?)"
|
|
;; with a parameter of 0 -- the nil value is inlined as NULL
|
|
```
|
|
|
|
`:inline` is an example of "special syntax" and it renders its
|
|
(single) argument as part of the SQL string generated by `format`.
|
|
|
|
Another form of special syntax that is treated as function calls
|
|
is keywords or symbols that begin with `%`. Such keywords (or symbols)
|
|
are split at `.` and turned into function calls:
|
|
|
|
```clojure
|
|
%now ;=> NOW()
|
|
%count.* ;=> COUNT(*)
|
|
%max.foo ;=> MAX(foo)
|
|
%f.a.b ;=> F(a,b)
|
|
```
|
|
|
|
## SQL Parameters
|
|
|
|
As indicated in the preceding sections, values found in the DSL data structure
|
|
that are not keywords or symbols are lifted out as positional parameters.
|
|
They are replaced by `?` in the generated SQL string and added to the
|
|
parameter list in order:
|
|
|
|
```clojure
|
|
[:between :size 10 20] ;=> "size BETWEEN ? AND ?" with parameters 10 and 20
|
|
```
|
|
|
|
HoneySQL also supports named parameters. There are two ways
|
|
of identifying a named parameter:
|
|
* a keyword or symbol that begins with `?`
|
|
* the `:param` special (functional) syntax
|
|
|
|
The values of those parameters are supplied in the `format`
|
|
call as the `:params` key of the options hash map.
|
|
|
|
```clojure
|
|
(sql/format {:select [:*] :from [:table]
|
|
:where [:= :a :?x]}
|
|
{:params {:x 42}})
|
|
["SELECT * FROM table WHERE a = ?" 42]
|
|
(sql/format {:select [:*] :from [:table]
|
|
:where [:= :a [:param :x]]}
|
|
{:params {:x 42}})
|
|
["SELECT * FROM table WHERE a = ?" 42]
|
|
```
|
|
|
|
## Functional Helpers
|
|
|
|
In addition to the hash map (and vectors) approach of building
|
|
SQL queries with raw Clojure data structures, a namespace full
|
|
of helper functions is also available. These functions are
|
|
generally variadic and threadable:
|
|
|
|
```clojure
|
|
(ns my.example
|
|
(:require [honey.sql :as sql]
|
|
[honey.sql.helpers :refer [select from where]]))
|
|
|
|
(-> (select :t/id [:name :item])
|
|
(from [:table :t])
|
|
(where [:= :id 1])
|
|
(sql/format))
|
|
;; produces:
|
|
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
There is a helper function for every single clause that HoneySQL
|
|
supports out of the box. In addition, there are helpers for
|
|
`composite` and `over` that make it easier to construct those
|
|
parts of the SQL DSL (examples of the former appear in the [README](README.md),
|
|
examples of the latter appear in the [Clause Reference](docs/clause-reference.md))
|
|
|
|
In addition to being variadic -- which often lets you omit one
|
|
level of `[`..`]` -- the helper functions merge clauses, which
|
|
can make it easier to build queries programmatically:
|
|
|
|
```clojure
|
|
(-> (select :t/id)
|
|
(from [:table :t])
|
|
(where [:= :id 1])
|
|
(select [:name :item])
|
|
(sql/format))
|
|
;; produces:
|
|
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
If you want to replace a clause with a subsequent helper call,
|
|
you need to explicitly remove the prior value:
|
|
|
|
```clojure
|
|
(-> (select :t/id)
|
|
(from [:table :t])
|
|
(where [:= :id 1])
|
|
(dissoc :select)
|
|
(select [:name :item])
|
|
(sql/format))
|
|
;; produces:
|
|
;;=> ["SELECT name AS item FROM table AS t WHERE id = ?" 1]
|
|
```
|
|
|
|
Helpers always use keywords when constructing clauses so you
|
|
can rely on using keywords in `dissoc`.
|
|
|
|
The following helpers shadow functions in `clojure.core` so
|
|
you need to consider this when referring symbols in from the
|
|
`honey.sql.helpers` namespace: `for`, `group-by`, `partition-by`,
|
|
`set`, and `update`.
|
|
|
|
## Dialects
|
|
|
|
By default, HoneySQL operates in ANSI SQL mode but it supports
|
|
a lot of PostgreSQL extensions in that mode. PostgreSQL is mostly
|
|
a superset of ANSI SQL so it makes sense to support as much as
|
|
possible of the union of ANSI SQL and PostgreSQL out of the box.
|
|
|
|
The dialects supported by HoneySQL v2 are:
|
|
* `:ansi` -- the default, including most PostgreSQL extensions
|
|
* `:sqlserver` -- Microsoft SQL Server
|
|
* `:mysql` -- MySQL (and Percona and MariaDB)
|
|
* `:oracle` -- Oracle
|
|
|
|
The most visible difference between dialects is how SQL entities
|
|
should be quoted (if the `:quoted true` option is provided to `format`).
|
|
Most databases use `"` for quoting (the `:ansi` and `:oracle` dialects).
|
|
The `:sqlserver` dialect uses `[`..`]` and the `:mysql` dialect uses
|
|
```..```.
|
|
|
|
Currently, the only dialect that has substantive differences from
|
|
the others is `:mysql` which has a `:lock` clause (that is very
|
|
similar to the ANSI `:for` clause) and for which the `:set` clause
|
|
has a different precedence than ANSI SQL.
|
|
|
|
You can change the dialect globally using the `set-dialect!` function,
|
|
passing in one of the keywords above. You need to call this function
|
|
before you call `format` for the first time.
|
|
|
|
You can change the dialect for a single `format` call by
|
|
specifying the `:dialect` option in that call.
|
|
|
|
SQL entities are not quoted by default but if you specify the
|
|
dialect in a `format` call, they will be quoted. If you don't
|
|
specify a dialect in the `format` call, you can specify
|
|
`:quoted true` to have SQL entities quoted.
|
|
|
|
```clojure
|
|
(sql/format '{select (id) from (table)} {:quoted true})
|
|
;;=> ["SELECT \"id\" FROM \"table\""]
|
|
(sql/format '{select (id) from (table)} {:dialect :mysql})
|
|
;;=> ["SELECT `id` FROM `table`"]
|
|
(sql/set-dialect! :sqlserver)
|
|
;;=> nil
|
|
(sql/format '{select (id) from (table)} {:quoted true})
|
|
;;=> ["SELECT [id] FROM [table]"]
|
|
```
|
|
|
|
Out of the box, as part of the extended ANSI SQL support,
|
|
HoneySQL supports quite a few [PostgreSQL extensions](docs/postgresql.md)
|
|
|
|
## Format Options
|
|
|
|
In addition to the `:quoted` and `:dialect` options described above,
|
|
`format` also accepts `:inline` and `:params`.
|
|
|
|
The `:params` option was mentioned above and is used to specify
|
|
the values of named parameters in the DSL.
|
|
|
|
The `:inline` option suppresses the generation of parameters in
|
|
the SQL string and instead tries to inline all the values directly
|
|
into the SQL string. The behavior is as if each value in the DSL
|
|
was wrapped in `[:inline `..`]`:
|
|
|
|
* `nil` becomes the SQL value `NULL`,
|
|
* Clojure strings become inline SQL strings with single quotes (so `"foo"` becomes `'foo'`),
|
|
* keywords and symbols become SQL keywords (uppercase, with `-` replaced by a space),
|
|
* everything else is just turned into a string (by calling `str`) and added to the SQL string.
|
|
|
|
## Reference Documentation
|
|
|
|
The full list of supported SQL clauses is documented in the
|
|
[docs/clause-reference.md](Clause Reference). The full list
|
|
of operators supported (as prefix-form "functions") is
|
|
documented in the [Operator Reference](docs/operator-reference.md)
|
|
section. The full list
|
|
of "special syntax" functions is documented in the
|
|
[Special Syntax](docs/special-syntax.md) section. The best
|
|
documentation for the helper functions is the
|
|
[https://cljdoc.org/d/seancorfield/honeysql/CURRENT/api/honey.sql.helpers](honey.sql.helpers).
|
|
If you're migrating to HoneySQL 2.0, this [overview of differences
|
|
between 1.0 and 2.0](docs/differences-from-1-x.md) should help.
|