From: drh <> Date: Mon, 10 Jan 2022 13:55:08 +0000 (+0000) Subject: New proposal for -> and ->> operators. X-Git-Tag: version-3.38.0~119^2~4 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=d3c6c3459b5aff110877428770e52df354c63360;p=thirdparty%2Fsqlite.git New proposal for -> and ->> operators. FossilOrigin-Name: 1108e12a2244edc6247050a0e9ad25b912bba6c57c71c51c2bc55167a6955175 --- diff --git a/doc/json-enhancements.md b/doc/json-enhancements.md index 8d83554ad2..d3ab6e0a43 100644 --- a/doc/json-enhancements.md +++ b/doc/json-enhancements.md @@ -3,110 +3,131 @@ This document summaries enhancements to the SQLite JSON support added in early 2022. -## 1.0 New feature summary: +## 1.0 Change summary: 1. New **->** and **->>** operators that work like MySQL and PostgreSQL (PG). - 2. New functions: **json_nextract()** and **json_ntype()**. - 3. JSON functions are built-in rather than being an extension. They + 2. JSON functions are built-in rather than being an extension. They are included by default, but can be omitted using the -DSQLITE_OMIT_JSON compile-time option. -## 2.0 The **json_nextract()** function. -The new **json_nextract()** function works like **json_extract()** with -one exception: if the input text in the first argument is not well-formed -JSON, then json_nextract() returns NULL whereas json_extract() raises -an error. The extra "n" in the name of json_nextract() can be throught -of as meaning "null-if-error". - -A call to json_nextract($JSON,$PATH) is logically equivalent to: - -> ~~~ -CASE WHEN json_valid($JSON) THEN json_extract($JSON,$PATH) END -~~~ - -The json_nextract() function is intended for use in tables where a -column might hold a mixture of datatypes - some rows holding JSON and other -rows holding primitive SQL datatypes such as INT, REAL, and TEXT. The -json_nextract() function makes it easier to write robust queries -against such tables. - -## 3.0 New operators **->** and **->>** +## 2.0 New operators **->** and **->>** The SQLite language adds two new binary operators **->** and **->>**. -The -> operator works like the two-argument version of json_nextract() -and the ->> operator works like the two-argument version of json_extract(). -The left-hand operand of -> and ->> is JSON. The right-hand operand -is a JSON path expression. These operators extract and return a value -from the left-hand JSON that is specified by right-hand path expression. - -The operators work exactly the same if the left-hand side is well-formed -JSON. The only difference is that if the left-hand side is not well-formed -JSON, the ->> raises an error whereas the -> operator simply returns NULL. - -### 3.1 Compatibility with MySQL - -The ->> operator should be compatible with MySQL in the sense that -a ->> operator that works in MySQL should work the same way in SQLite. -But (see below) the SQLite ->> operator is also extended to support PG -syntax so not every use of ->> that wworks in SQLite will work for MySQL. - -The -> operator is *mostly* compatible with MySQL. Key differences -between the SQLite -> operator and the MySQL -> operator are: - - * The SQLite -> operator returns NULL if the left-hand side is - not well-formed JSON whereas MySQL will raise an error. - - * When the JSON path expression on the right-hand side selects a - text value from the JSON, the -> operator in MySQL returns the - string quoted as if for JSON, whereas the SQLite -> operator - returns an unquoted SQL text value. - -This second difference - the handling of text values extracted from JSON - -is also a difference in the json_extract() function between SQLite and -MySQL. Because json_extract() has been in active use for 6 years, and -because the SQLite semantics seem to be more useful, there -are no plans to change json_extract() to make it compatible with MySQL. - -### 3.2 Compatibility with PostgreSQL (PG) - -The ->> operator in PG does not accept a JSON path expression as its -right-hand operand. Instead, PG looks for either a text string X -(which is then interpreted as the path "$.X") or an integer N (which -is then interpreted as "$[N]"). In order to make the SQLite ->> operator -compatible with the PG ->> operator, the SQLite ->> operator has been -extended so that its right-hand operand can be either a text label or -a integer array index, as it is in PG. The SQLite ->> operator also -accepts full JSON path expressions as well. - -The enhancement of accepting JSON path expression that consist of just -a bare object label or array index is unique to the -> and ->> operators. -All other places in the SQLite JSON interface that require JSON path -expressions continue to require well-formed JSON path expressions. -Only -> and ->> accept the PG-compatible abbreviated path expressions. - -The -> operator in SQLite is *mostly* compatible with the -> operator -in PG. The differences are the same as for MySQL. - -## 4.0 The **json_ntype()** function. - -The **json_ntype()** function works like **json_type()** except that when -the argument is not well-formed JSON, the json_ntype() function returns -NULL whereas json_type() raises an error. The extra "n" in the name can -be understood as standing for "null-if-error". - -The json_ntype($JSON) function is logically equivalent to: - -> ~~~ -CASE WHEN json_valid($JSON) THEN json_type($JSON) END -~~~ - -The json_ntype() function can be seen as an enhanced version of -the json_valid() function, that in addition to indicating whether or -not the string is well-formed JSON, also indicates the top-level type -of that JSON. - -## 5.0 JSON moved into the core +Both operators are similar to json_extract(). The left operand is +JSON and the right operand is a JSON path expression (possibly abbreviated +for compatibility with PG - see below). So they are similar to a +two-argument call to json_extract(). + +The difference between -> and ->> (and json_extract()) is as follows: + + * The -> operator always returns JSON. + + * The ->> operator converts the answer into a primitive SQL datatype + such as TEXT, INTEGER, REAL, or NULL. If a JSON object or array + is selected, that object or array is rendered as text. If a JSON + value is selected, that value is converted into its corresponding + SQL type + + * The json_extract() interface returns JSON when a JSON object or + array is selected, or a primitive SQL datatype when a JSON value + is selected. This is different from MySQL, in which json_extract() + always returns JSON, but the difference is retained because it has + worked that way for 6 years and changing it now would likely break + a lot of legacy code. + +In MySQL and PG, the ->> operator always returns TEXT (or NULL) and never +INTEGER or REAL. This is due to limitations in the type handling capabilities +of those systems. In MySQL and PG, the result type a function or operator +may only depend on the type of its arguments, never the value of its arguments. +But the underlying JSON type depends on the value of the JSON path +expression, not the type of the JSON path expression (which is always TEXT). +Hence, the result type of ->> in MySQL and PG is unable to vary according +to the type of the JSON value being extracted. + +The type system in SQLite is more general. Functions in SQLite are able +to return different datatypes depending on the value of their arguments. +So the ->> operator in SQLite is able to return TEXT, INTEGER, REAL, or NULL +depending on the JSON type of the value being extracted. This means that +the behavior of the ->> is slightly different in SQLite versus MySQL and PG +in that it will sometimes return INTEGER and REAL values, depending on its +inputs. It is possible to implement the ->> operator in SQLite so that it +always operates exactly like MySQL and PG and always returns TEXT or NULL, +but I have been unable to think of any situations where returning the +actual JSON value this would cause problems, so I'm including the enhanced +functionality in SQLite. + +The table below attempts to summarize the differences between the +-> and ->> operators and the json_extract() function, for SQLite, MySQL, +and PG. JSON values are shown using their SQL text representation but +in a bold font. + + +
JSON | PATH | -> operator (all) | ->> operator (MySQL/PG) + | ->> operator (SQLite) | json_extract() (SQLite) + |
---|---|---|---|---|---|
**'{"a":123}'** | '$.a' | **'123'** | '123' | 123 | 123 + |
**'{"a":4.5}'** | '$.a' | **'4.5'** | '4.5' | 4.5 | 4.5 + |
**'{"a":"xyz"}'** | '$.a' | **'"xyz"'** | 'xyz' | 'xyz' | 'xyz' + |
**'{"a":null}'** | '$.a' | **'null'** | NULL | NULL | NULL + |
**'{"a":[6,7,8]}'** | '$.a' | **'[6,7,8]'** | '[6,7,8]' | '[6,7,8]' | **'[6,7,9]'** + |
**'{"a":{"x":9}}'** | '$.a' | **'{"x":9}'** | '{"x":9}' | '{"x":9}' | **'{"x":9}'** + |
**'{"b":999}'** | '$.a' | NULL | NULL | NULL | NULL + |
SQL expression | Works in MySQL? | Works in PG? | Works in SQLite + |
---|---|---|---|
value1->'$.a' | yes | no | yes + |
value1->'a' | no | yes | yes + |
value2->'$[2]' | yes | no | yes + |
value2->2 | no | yes | yes + |