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
|
[](https://travis-ci.org/postgrespro/jsquery)
[](https://codecov.io/gh/postgrespro/jsquery)
[](https://raw.githubusercontent.com/postgrespro/jsquery/master/LICENSE)
JsQuery – json query language with GIN indexing support
=======================================================
Introduction
------------
JsQuery – is a language to query jsonb data type, introduced in PostgreSQL
release 9.4.
It's primary goal is to provide an additional functionality to jsonb
(currently missing in PostgreSQL), such as a simple and effective way
to search in nested objects and arrays, more comparison operators with
indexes support. We hope, that jsquery will be eventually a part of
PostgreSQL.
Jsquery is released as jsquery data type (similar to tsquery) and @@
match operator for jsonb.
Authors
-------
* Teodor Sigaev <teodor@sigaev.ru>, Postgres Professional, Moscow, Russia
* Alexander Korotkov <aekorotkov@gmail.com>, Postgres Professional, Moscow, Russia
* Oleg Bartunov <oleg@sai.msu.su>, Postgres Professional, Moscow, Russia
Availability
------------
JsQuery is realized as an extension and not available in default PostgreSQL
installation. It is available from
[github](https://github.com/postgrespro/jsquery)
under the same license as
[PostgreSQL](https://www.postgresql.org/about/licence/)
and supports PostgreSQL 9.4+.
Regards
-------
Development was sponsored by [Wargaming.net](http://wargaming.net).
Installation
------------
JsQuery is PostgreSQL extension which requires PostgreSQL 9.4 or higher.
Before build and install you should ensure following:
* PostgreSQL version is 9.4 or higher.
* You have development package of PostgreSQL installed or you built
PostgreSQL from source.
* You have flex and bison installed on your system. JsQuery was tested on
flex 2.5.37-2.5.39, bison 2.7.12.
* Your PATH variable is configured so that pg\_config command available, or set PG_CONFIG variable.
Typical installation procedure may look like this:
$ git clone https://github.com/postgrespro/jsquery.git
$ cd jsquery
$ make USE_PGXS=1
$ sudo make USE_PGXS=1 install
$ make USE_PGXS=1 installcheck
$ psql DB -c "CREATE EXTENSION jsquery;"
JSON query language
-------------------
JsQuery extension contains `jsquery` datatype which represents whole JSON query
as a single value (like `tsquery` does for fulltext search). The query is an
expression on JSON-document values.
Simple expression is specified as `path binary_operator value` or
`path unary_operator`. See following examples.
* `x = "abc"` – value of key "x" is equal to "abc";
* `$ @> [4, 5, "zzz"]` – the JSON document is an array containing values
4, 5 and "zzz";
* `"abc xyz" >= 10` – value of key "abc xyz" is greater than or equal to 10;
* `volume IS NUMERIC` – type of key "volume" is numeric.
* `$ = true` – the whole JSON document is just a true.
* `similar_ids.@# > 5` – similar\_ids is an array or object of length greater
than 5;
* `similar_product_ids.# = "0684824396"` – array "similar\_product\_ids"
contains string "0684824396".
* `*.color = "red"` – there is object somewhere which key "color" has value
"red".
* `foo = *` – key "foo" exists in object.
Path selects set of JSON values to be checked using given operators. In
the simplest case path is just an key name. In general path is key names and
placeholders combined by dot signs. Path can use following placeholders:
* `#` – any index of array;
* `#N` – N-th index of array;
* `%` – any key of object;
* `*` – any sequence of array indexes and object keys;
* `@#` – length of array or object, could be only used as last component of
path;
* `$` – the whole JSON document as single value, could be only the whole path.
Expression is true when operator is true against at least one value selected
by path.
Key names could be given either with or without double quotes. Key names
without double quotes shouldn't contain spaces, start with number or concur
with jsquery keyword.
The supported binary operators are:
* Equality operator: `=`;
* Numeric comparison operators: `>`, `>=`, `<`, `<=`;
* Search in the list of scalar values using `IN` operator;
* Array comparison operators: `&&` (overlap), `@>` (contains),
`<@` (contained in).
The supported unary operators are:
* Check for existence operator: `= *`;
* Check for type operators: `IS ARRAY`, `IS NUMERIC`, `IS OBJECT`, `IS STRING`
and `IS BOOLEAN`.
Expressions could be complex. Complex expression is a set of expressions
combined by logical operators (`AND`, `OR`, `NOT`) and grouped using braces.
Examples of complex expressions are given below.
* `a = 1 AND (b = 2 OR c = 3) AND NOT d = 1`
* `x.% = true OR x.# = true`
Prefix expressions are expressions given in the form path (subexpression).
In this case path selects JSON values to be checked using given subexpression.
Check results are aggregated in the same way as in simple expressions.
* `#(a = 1 AND b = 2)` – exists element of array which a key is 1 and b key is 2
* `%($ >= 10 AND $ <= 20)` – exists object key which values is between 10 and 20
Path also could contain following special placeholders with "every" semantics:
* `#:` – every indexes of array;
* `%:` – every key of object;
* `*:` – every sequence of array indexes and object keys.
Consider following example.
%.#:($ >= 0 AND $ <= 1)
This example could be read as following: there is at least one key which value
is array of numerics between 0 and 1.
We can rewrite this example in the following form with extra braces.
%(#:($ >= 0 AND $ <= 1))
The first placeholder `%` checks that expression in braces is true for at least
one value in object. The second placeholder `#:` checks value to be array and
all its elements satisfy expressions in braces.
We can rewrite this example without `#:` placeholder as follows.
%(NOT #(NOT ($ >= 0 AND $ <= 1)) AND $ IS ARRAY)
In this example we transform assertion that every element of array satisfy some
condition to assertion that there is no one element which doesn't satisfy the
same condition.
Some examples of using paths are given below.
* `numbers.#: IS NUMERIC` – every element of "numbers" array is numeric.
* `*:($ IS OBJECT OR $ IS BOOLEAN)` – JSON is a structure of nested objects
with booleans as leaf values.
* `#:.%:($ >= 0 AND $ <= 1)` – each element of array is object containing
only numeric values between 0 and 1.
* `documents.#:.% = *` – "documents" is array of objects containing at least
one key.
* `%.#: ($ IS STRING)` – JSON object contains at least one array of strings.
* `#.% = true` – at least one array element is objects which contains at least
one "true" value.
Usage of path operators and braces need some explanation. When same path
operators are used multiple times they may refer different values while you can
refer same value multiple time by using braces and `$` operator. See following
examples.
* `# < 10 AND # > 20` – exists element less than 10 and exists another element
greater than 20.
* `#($ < 10 AND $ > 20)` – exists element which both less than 10 and greater
than 20 (impossible).
* `#($ >= 10 AND $ <= 20)` – exists element between 10 and 20.
* `# >= 10 AND # <= 20` – exists element great or equal to 10 and exists
another element less or equal to 20. Query can be satisfied by array with
no elements between 10 and 20, for instance [0,30].
Same rules apply when you search inside objects and branchy structures.
Type checking operators and "every" placeholders are useful for document
schema validation. JsQuery matchig operator `@@` is immutable and can be used
in CHECK constraint. See following example.
```sql
CREATE TABLE js (
id serial,
data jsonb,
CHECK (data @@ '
name IS STRING AND
similar_ids.#: IS NUMERIC AND
points.#:(x IS NUMERIC AND y IS NUMERIC)'::jsquery));
```
In this example check constraint validates that in "data" jsonb column:
value of "name" key is string, value of "similar_ids" key is array of numerics,
value of "points" key is array of objects which contain numeric values in
"x" and "y" keys.
See our
[pgconf.eu presentation](http://www.sai.msu.su/~megera/postgres/talks/pgconfeu-2014-jsquery.pdf)
for more examples.
GIN indexes
-----------
JsQuery extension contains two operator classes (opclasses) for GIN which
provide different kinds of query optimization.
* jsonb\_path\_value\_ops
* jsonb\_value\_path\_ops
In each of two GIN opclasses jsonb documents are decomposed into entries. Each
entry is associated with particular value and it's path. Difference between
opclasses is in the entry representation, comparison and usage for search
optimization.
For example, jsonb document
`{"a": [{"b": "xyz", "c": true}, 10], "d": {"e": [7, false]}}`
would be decomposed into following entries:
* "a".#."b"."xyz"
* "a".#."c".true
* "a".#.10
* "d"."e".#.7
* "d"."e".#.false
Since JsQuery doesn't support search in particular array index, we consider
all array elements to be equivalent. Thus, each array element is marked with
same `#` sign in the path.
Major problem in the entries representation is its size. In the given example
key "a" is presented three times. In the large branchy documents with long
keys size of naive entries representation becomes unreasonable. Both opclasses
address this issue but in a slightly different way.
### jsonb\_path\_value\_ops
jsonb\_path\_value\_ops represents entry as pair of path hash and value.
Following pseudocode illustrates it.
(hash(path_item_1.path_item_2. ... .path_item_n); value)
In comparison of entries path hash is the higher part of entry and value is
its lower part. This determines the features of this opclass. Since path
is hashed and it is higher part of entry we need to know the full path to
the value in order to use it for search. However, once path is specified
we can use both exact and range searches very efficiently.
### jsonb\_value\_path\_ops
jsonb\_value\_path\_ops represents entry as pair of value and bloom filter
of path.
(value; bloom(path_item_1) | bloom(path_item_2) | ... | bloom(path_item_n))
In comparison of entries value is the higher part of entry and bloom filter of
path is its lower part. This determines the features of this opclass. Since
value is the higher part of entry we can perform only exact value search
efficiently. Range value search is possible as well but we would have to
filter all the the different paths where matching values occur. Bloom filter
over path items allows index usage for conditions containing `%` and `*` in
their paths.
### Query optimization
JsQuery opclasses perform complex query optimization. Thus it's valuable for
developer or administrator to see the result of such optimization.
Unfortunately, opclasses aren't allowed to do any custom output to the
EXPLAIN. That's why JsQuery provides following functions which allows to see
how particular opclass optimizes given query.
* gin\_debug\_query\_path\_value(jsquery) – for jsonb\_path\_value\_ops
* gin\_debug\_query\_value\_path(jsquery) – for jsonb\_value\_path\_ops
Result of these functions is a textual representation of query tree which
leafs are GIN search entries. Following examples show different results of
query optimization by different opclasses.
# SELECT gin_debug_query_path_value('x = 1 AND (*.y = 1 OR y = 2)');
gin_debug_query_path_value
----------------------------
x = 1 , entry 0 +
# SELECT gin_debug_query_value_path('x = 1 AND (*.y = 1 OR y = 2)');
gin_debug_query_value_path
----------------------------
AND +
x = 1 , entry 0 +
OR +
*.y = 1 , entry 1 +
y = 2 , entry 2 +
Unfortunately, jsonb have no statistics yet. That's why JsQuery optimizer has
to do imperative decision while selecting conditions to be evaluated using
index. This decision is made by assumtion that some condition types are less
selective than others. Optimizer divides conditions into following selectivity
class (listed by descending of selectivity).
1. Equality (x = c)
2. Range (c1 < x < c2)
3. Inequality (x > c)
4. Is (x is type)
5. Any (x = \*)
Optimizer evades index evaluation of less selective conditions when possible.
For example, in the `x = 1 AND y > 0` query `x = 1` is assumed to be more
selective than `y > 0`. That's why index isn't used for evaluation of `y > 0`.
# SELECT gin_debug_query_path_value('x = 1 AND y > 0');
gin_debug_query_path_value
----------------------------
x = 1 , entry 0 +
With lack of statistics decisions made by optimizer can be inaccurate. That's
why JsQuery supports hints. Comments `/*-- index */` and `/*-- noindex */`
placed in the conditions forces optimizer to use and not use index
correspondingly.
SELECT gin_debug_query_path_value('x = 1 AND y /*-- index */ > 0');
gin_debug_query_path_value
----------------------------
AND +
x = 1 , entry 0 +
y > 0 , entry 1 +
SELECT gin_debug_query_path_value('x /*-- noindex */ = 1 AND y > 0');
gin_debug_query_path_value
----------------------------
y > 0 , entry 0 +
Contribution
------------
Please, notice, that JsQuery is still under development and while it's
stable and tested, it may contains some bugs. Don't hesitate to raise
[issues at github](https://github.com/postgrespro/jsquery/issues) with your
bug reports.
If you're lacking of some functionality in JsQuery and feeling power to
implement it then you're welcome to make pull requests.
|