1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362
|
# 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:
<!-- :test-doc-blocks/skip -->
```clojure
com.github.seancorfield/honeysql {:mvn/version "2.3.911"}
```
For Leiningen, add the following dependency to your `project.clj` file:
<!-- :test-doc-blocks/skip -->
```clojure
[com.github.seancorfield/honeysql "2.3.911"]
```
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.
You can also experiment with HoneySQL directly in a browser -- no installation
required -- using [John Shaffer](https://github.com/john-shaffer)'s awesome
[HoneySQL web app](https://www.john-shaffer.com/honeysql/), written in ClojureScript!
## Basic Concepts
SQL statements are represented as hash maps, with keys that
represent clauses in SQL. SQL expressions are generally
represented as sequences, 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
(require '[honey.sql :as sql])
(sql/format {:select [:*], :from [:table], :where [:= :id 1]})
;;=> ["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 sequence 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 more 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]})
;;=> ["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]})
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
;; or you can use (..) instead of [..] when quoted to produce the same result:
(sql/format '{select (t.id (name item)), from ((table t)), where (= id 1)})
;;=> ["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
;; notice the following both produce the same result:
(sql/format {:select [:t/id [:name :item]], :from [[:table :t]], :where [:= :id 1]})
;;=> ["SELECT t.id, name AS item FROM table AS t WHERE id = ?" 1]
(sql/format '{select [t/id [name item]], from [[table t]], where [= id 1]})
;;=> ["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 sequences 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](special-syntax.md) section.
Some examples:
<!-- :test-doc-blocks/skip -->
```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:
<!-- :test-doc-blocks/skip -->
```clojure
%now ;=> NOW()
%count.* ;=> COUNT(*)
%max.foo ;=> MAX(foo)
%f.a.b ;=> F(a,b)
```
If you need to reference a table or alias for a column, you can use
qualified names in a function invocation:
<!-- :test-doc-blocks/skip -->
```clojure
%max.foo/bar ;=> MAX(foo.bar)
```
The latter syntax can be convenient in a `SELECT` because `[:a :b]` is
otherwise taken as a column and its alias, so selecting a function call
expression requires an extra level of nesting:
```clojure
(sql/format {:select [:a]})
;;=> ["SELECT a"]
(sql/format {:select [[:a :b]]})
;;=> ["SELECT a AS b"]
(sql/format {:select [[[:a :b]]]})
;;=> ["SELECT A(b)"]
;; or use the % notification:
(sql/format {:select [:%a.b]})
;;=> ["SELECT A(b)"]
(sql/format {:select [[[:a :b] :c]]})
;;=> ["SELECT A(b) AS c"]
(sql/format {:select [[:%a.b :c]]})
;;=> ["SELECT A(b) AS c"]
;; putting it all together:
(sql/format {:select [:x [:y :d] [[:z :e]] [[:z :f] :g]]})
;;=> ["SELECT x, y AS d, Z(e), Z(f) AS g"]
(sql/format {:select [:x [:y :d] [:%z.e] [:%z.f :g]]})
;;=> ["SELECT x, y AS d, Z(e), Z(f) AS g"]
```
## 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:
<!-- :test-doc-blocks/skip -->
```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 sequences) approach of building
SQL queries with raw Clojure data structures, a
[namespace full of helper functions](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/api/honey.sql.helpers)
is also available. These functions are generally variadic and threadable:
```clojure
(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))
;;=> ["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`, `lateral`, `over`, and `upsert` that make it easier to construct those
parts of the SQL DSL (examples of `composite` appear in the [README](/README.md),
examples of `over` appear in the [Clause Reference](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))
;;=> ["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))
;;=> ["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: `filter`, `for`, `group-by`, `into`, `partition-by`,
`set`, and `update`.
## DDL Statements
HoneySQL 1.x did not support any DDL statements. It was fairly
common for people to use the
[nilenso/honeysql-postgres library](https://github.com/nilenso/honeysql-postgres)
to get DDL support, even if they didn't need the PostgreSQL-specific
extensions. That library does not work with HoneySQL 2.x but all
of the functionality from it (up to 0.4.112) has been incorporated
into HoneySQL now and is described in the [PostgreSQL](postgresql.md)
section (because that covers all of the things that the nilenso
library supported and much of it was PostgreSQL-specific!).
See also the [DDL Clauses section](clause-reference.md#ddl-clauses) of
the Clause Reference for documentation about supported DDL.
## 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 2.x 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
```..```. In addition, the `:oracle` dialect disables `AS` in aliases.
Currently, the only dialect that has substantive differences from
the others is `:mysql` 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.
<!-- Reminder to doc author:
Reset dialect to default so other blocks are not affected for test-doc-blocks -->
```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]"]
;; you can also choose to enable quoting globally
;; when you set a dialect:
(sql/set-dialect! :mysql :quoted true)
(sql/format '{select (id) from (table)})
;;=> ["SELECT `id` FROM `table`"]
;; and opt out for a specific call:
(sql/format '{select (id) from (table)} {:quoted false})
;;=> ["SELECT id FROM table"]
;; and reset back to the default of :ansi
(sql/set-dialect! :ansi)
;;=> 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](postgresql.md).
> Note: the [nilenso/honeysql-postgres](https://github.com/nilenso/honeysql-postgres) library which provided PostgreSQL support for HoneySQL 1.x does not work with HoneySQL 2.x. However, HoneySQL 2.x includes all of the functionality from that library (up to 0.4.112) out of the box!
## Reference Documentation
The full list of supported SQL clauses is documented in the
[Clause Reference](clause-reference.md). The full list
of operators supported (as prefix-form "functions") is
documented in the [Operator Reference](operator-reference.md)
section. The full list
of "special syntax" functions is documented in the
[Special Syntax](special-syntax.md) section. The best
documentation for the helper functions is in the
[honey.sql.helpers](https://cljdoc.org/d/com.github.seancorfield/honeysql/CURRENT/api/honey.sql.helpers) namespace.
More detail about certain core HoneySQL functionality can be found in the
[Reference documentation](general-reference.md).
If you're migrating to HoneySQL 2.x, this [overview of differences
between 1.x and 2.x](differences-from-1-x.md) should help.
|