add security notes about quoting

also consistently use SQL entity names instead of identifiers so the
documentation is consistent in terminology.
This commit is contained in:
Sean Corfield 2022-08-23 17:18:00 -07:00
parent a879a2d8a1
commit e204f3b45e
6 changed files with 28 additions and 19 deletions

View file

@ -703,11 +703,11 @@ INSERT INTO sample
0.291 32.621 4325]
```
#### Identifiers
#### Entity Names
To quote identifiers, pass the `:quoted true` option to `format` and they will
To quote SQL entity names, pass the `:quoted true` option to `format` and they will
be quoted according to the selected dialect. If you override the dialect in a
`format` call, by passing the `:dialect` option, identifiers will be automatically
`format` call, by passing the `:dialect` option, SQL entity names will be automatically
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`:

View file

@ -106,7 +106,7 @@ You can now select a non-ANSI dialect of SQL using the new `honey.sql/set-dialec
The `:quoting <dialect>` option has superseded by the new dialect machinery and a new `:quoted` option that turns quoting on or off. You either use `:dialect <dialect>` instead or set a default dialect (via `set-dialect!`) and then use `:quoted true` in `format` calls where you want quoting.
Identifiers are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`.
SQL entity names are automatically quoted if you specify a `:dialect` option to `format`, unless you also specify `:quoted false`.
The following options are no longer supported:
* `:allow-dashed-names?` -- if you provide dashed-names in 2.x, they will be left as-is if quoting is enabled, else they will be converted to snake_case (so you will either get `"dashed-names"` with quoting or `dashed_names` without). If you want dashed-names to be converted to snake_case when `:quoted true`, you also need to specify `:quoted-snake true`.

View file

@ -179,10 +179,10 @@ of it and would call `sql/format-expr` on each argument:
_New in HoneySQL 2.3.x_
The built-in dialects that HoneySQL supports are:
* `:ansi` -- the default, that quotes identifiers with double-quotes, like `"this"`
* `:mysql` -- quotes identifiers with backticks, and changes the precedence of `SET` in `UPDATE`
* `:oracle` -- quotes identifiers like `:ansi`, and does not use `AS` in aliases
* `:sqlserver` -- quotes identifiers with brackets, like `[this]`
* `:ansi` -- the default, that quotes SQL entity names with double-quotes, like `"this"`
* `:mysql` -- quotes SQL entity names with backticks, and changes the precedence of `SET` in `UPDATE`
* `:oracle` -- quotes SQL entity names like `:ansi`, and does not use `AS` in aliases
* `:sqlserver` -- quotes SQL entity names with brackets, like `[this]`
A dialect spec is a hash map containing at least `:quote` but also optionally `:clause-order-fn` and/or `:as`:
* `:quote` -- a unary function that takes a string and returns the quoted version of it

View file

@ -298,6 +298,8 @@ 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.
> Note: by default, quoting is **off** which produces cleaner-looking SQL and assumes you control all the symbols/keywords used as table, column, and function names -- the "SQL entities". If you are building any SQL or DDL where the table, column, or function names could be provided by an external source, **you should specify `:quoted true` to ensure all SQL entities are safely quoted**. As of 2.3.next, if you do _not_ specify `:quoted` as an option, HoneySQL will automatically quote any SQL entities that seem unusual, i.e., that contain any characters that are not alphanumeric or underscore. Purely alphanumeric entities will not be quoted (no entities were quoted by default prior to 2.3.next). You can prevent that auto-quoting by explicitly passing `:quoted false` into the `format` call but, from a security point of view, you should think very carefully before you do that: quoting entity names helps protect you from injection attacks!
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.
@ -309,10 +311,11 @@ 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
Alphanumeric 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.
`:quoted true` to have SQL entities quoted. You can also enable quoting
globally via the `set-dialect!` function.
<!-- Reminder to doc author:
Reset dialect to default so other blocks are not affected for test-doc-blocks -->

View file

@ -20,8 +20,8 @@ All options may be omitted. The default behavior of each option is described in
* `:dialect` -- a keyword that identifies a dialect to be used for this specific call to `format`; the default is to use what was specified in `set-dialect!` or `:ansi` if no other dialect has been set,
* `:inline` -- a Boolean indicating whether or not to inline parameter values, rather than use `?` placeholders and a sequence of parameter values; the default is `false` -- values are not inlined,
* `:params` -- a hash map providing values for named parameters, identified by names (keywords or symbols) that start with `?` in the DSL; the default is that any such named parameters will have `nil` values,
* `:quoted` -- a Boolean indicating whether or not to quote (strop) identifiers (table and column names); the default is `false` -- identifiers are not quoted,
* `:quoted-snake` -- a Boolean indicating whether or not quoted and string identifiers should have `-` replaced by `_`; the default is `false` -- quoted and string identifiers are left exactly as-is,
* `:quoted` -- a Boolean indicating whether or not to quote (strop) SQL entity names (table and column names); the default is `nil` -- alphanumeric SQL entity names are not quoted but (as of 2.3.next) "unusual" SQL entity names are quoted; a `false` value turns off all quoting,
* `:quoted-snake` -- a Boolean indicating whether or not quoted and string SQL entity names should have `-` replaced by `_`; the default is `false` -- quoted and string SQL entity names are left exactly as-is,
* `:values-default-columns` -- a sequence of column names that should have `DEFAULT` values instead of `NULL` values if used in a `VALUES` clause with no associated matching value in the hash maps passed in; the default behavior is for such missing columns to be given `NULL` values.
See below for the interaction between `:dialect` and `:quoted`.
@ -104,12 +104,12 @@ to values for this call to `format`. For example:
## `:quoted`
If `:quoted true`, or `:dialect` is provided (and `:quoted` is not
specified as `false`), identifiers that represent
specified as `false`), SQL entity names that represent
tables and columns will be quoted (stropped) according to the
selected dialect.
If `:quoted false`, identifiers that represent tables and columns
will not be quoted. If those identifiers are reserved words in
If `:quoted false`, SQL entity names that represent tables and columns
will not be quoted. If those SQL entity names are reserved words in
SQL, the generated SQL will be invalid.
The quoting (stropping) is dialect-dependent:
@ -118,19 +118,23 @@ The quoting (stropping) is dialect-dependent:
* `:oracle` -- uses double quotes
* `:sqlserver` -- user square brackets
As of 2.3.next, if `:quoted` and `:dialect` are not provided, and no
default quoting strategy has been specified (via `set-dialect!`) then
alphanumeric SQL entity names will not be quoted but "unusual" SQL entity names will
## `:quoted-snake`
Where strings are used to identify table or column names, they are
treated as-is. If `:quoted true` (or a `:dialect` is specified),
those identifiers are quoted as-is.
those SQL entity names are quoted as-is.
Where keywords or symbols are used to identify table or column
names, and `:quoted true` is provided, those identifiers are
names, and `:quoted true` is provided, those SQL entity names are
quoted as-is.
If `:quoted-snake true` is provided, those identifiers are quoted
If `:quoted-snake true` is provided, those SQL entity names are quoted
but any `-` in them are replaced by `_` -- that replacement is the
default in unquoted identifiers.
default in unquoted SQL entity names.
This allows quoting to be used but still maintain the Clojure
(kebab case) to SQL (snake case) mappings.

View file

@ -738,6 +738,8 @@ ORDER BY id = ? DESC
:enabled enabled}]})))))
(deftest issue-316-test
;; this is a pretty naive test -- there are other tricks to perform injection
;; that are not detected by HoneySQL and you should generally use :quoted true
(testing "SQL injection via keyword is detected"
(let [sort-column "foo; select * from users"]
(try