mirror of https://github.com/postgres/postgres
GIN support for @@ and @? jsonpath operators
This commit makes existing GIN operator classes jsonb_ops and json_path_ops support "jsonb @@ jsonpath" and "jsonb @? jsonpath" operators. Basic idea is to extract statements of following form out of jsonpath. key1.key2. ... .keyN = const The rest of jsonpath is rechecked from heap. Catversion is bumped. Discussion: https://postgr.es/m/fcc6fc6a-b497-f39a-923d-aa34d0c588e8%402ndQuadrant.com Author: Nikita Glukhov, Alexander Korotkov Reviewed-by: Jonathan Katz, Pavel Stehule
This commit is contained in:
parent
7241911782
commit
0a02e2ae02
|
@ -102,6 +102,8 @@
|
|||
<literal>?&</literal>
|
||||
<literal>?|</literal>
|
||||
<literal>@></literal>
|
||||
<literal>@?</literal>
|
||||
<literal>@@</literal>
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
|
@ -109,6 +111,8 @@
|
|||
<entry><type>jsonb</type></entry>
|
||||
<entry>
|
||||
<literal>@></literal>
|
||||
<literal>@?</literal>
|
||||
<literal>@@</literal>
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
|
|
|
@ -480,6 +480,22 @@ CREATE INDEX idxgintags ON api USING GIN ((jdoc -> 'tags'));
|
|||
(More information on expression indexes can be found in <xref
|
||||
linkend="indexes-expressional"/>.)
|
||||
</para>
|
||||
<para>
|
||||
Also, GIN index supports <literal>@@</literal> and <literal>@?</literal>
|
||||
operators, which perform <literal>jsonpath</literal> matching.
|
||||
<programlisting>
|
||||
SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @@ '$.tags[*] == "qui"';
|
||||
</programlisting>
|
||||
<programlisting>
|
||||
SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @@ '$.tags[*] ? (@ == "qui")';
|
||||
</programlisting>
|
||||
GIN index extracts statements of following form out of
|
||||
<literal>jsonpath</literal>: <literal>accessors_chain = const</literal>.
|
||||
Accessors chain may consist of <literal>.key</literal>,
|
||||
<literal>[*]</literal> and <literal>[index]</literal> accessors.
|
||||
<literal>jsonb_ops</literal> additionally supports <literal>.*</literal>
|
||||
and <literal>.**</literal> statements.
|
||||
</para>
|
||||
<para>
|
||||
Another approach to querying is to exploit containment, for example:
|
||||
<programlisting>
|
||||
|
@ -498,7 +514,8 @@ SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @> '{"tags": ["qu
|
|||
|
||||
<para>
|
||||
Although the <literal>jsonb_path_ops</literal> operator class supports
|
||||
only queries with the <literal>@></literal> operator, it has notable
|
||||
only queries with the <literal>@></literal>, <literal>@@</literal>
|
||||
and <literal>@?</literal> operators, it has notable
|
||||
performance advantages over the default operator
|
||||
class <literal>jsonb_ops</literal>. A <literal>jsonb_path_ops</literal>
|
||||
index is usually much smaller than a <literal>jsonb_ops</literal>
|
||||
|
|
File diff suppressed because it is too large
Load Diff
|
@ -53,6 +53,6 @@
|
|||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 201903301
|
||||
#define CATALOG_VERSION_NO 201904011
|
||||
|
||||
#endif
|
||||
|
|
|
@ -1468,11 +1468,23 @@
|
|||
{ amopfamily => 'gin/jsonb_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => '_text', amopstrategy => '11', amopopr => '?&(jsonb,_text)',
|
||||
amopmethod => 'gin' },
|
||||
{ amopfamily => 'gin/jsonb_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => 'jsonpath', amopstrategy => '15',
|
||||
amopopr => '@?(jsonb,jsonpath)', amopmethod => 'gin' },
|
||||
{ amopfamily => 'gin/jsonb_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => 'jsonpath', amopstrategy => '16',
|
||||
amopopr => '@@(jsonb,jsonpath)', amopmethod => 'gin' },
|
||||
|
||||
# GIN jsonb_path_ops
|
||||
{ amopfamily => 'gin/jsonb_path_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => 'jsonb', amopstrategy => '7', amopopr => '@>(jsonb,jsonb)',
|
||||
amopmethod => 'gin' },
|
||||
{ amopfamily => 'gin/jsonb_path_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => 'jsonpath', amopstrategy => '15',
|
||||
amopopr => '@?(jsonb,jsonpath)', amopmethod => 'gin' },
|
||||
{ amopfamily => 'gin/jsonb_path_ops', amoplefttype => 'jsonb',
|
||||
amoprighttype => 'jsonpath', amopstrategy => '16',
|
||||
amopopr => '@@(jsonb,jsonpath)', amopmethod => 'gin' },
|
||||
|
||||
# SP-GiST range_ops
|
||||
{ amopfamily => 'spgist/range_ops', amoplefttype => 'anyrange',
|
||||
|
|
|
@ -34,6 +34,9 @@ typedef enum
|
|||
#define JsonbExistsStrategyNumber 9
|
||||
#define JsonbExistsAnyStrategyNumber 10
|
||||
#define JsonbExistsAllStrategyNumber 11
|
||||
#define JsonbJsonpathExistsStrategyNumber 15
|
||||
#define JsonbJsonpathPredicateStrategyNumber 16
|
||||
|
||||
|
||||
/*
|
||||
* In the standard jsonb_ops GIN opclass for jsonb, we choose to index both
|
||||
|
|
|
@ -35,6 +35,8 @@ typedef struct
|
|||
#define PG_GETARG_JSONPATH_P_COPY(x) DatumGetJsonPathPCopy(PG_GETARG_DATUM(x))
|
||||
#define PG_RETURN_JSONPATH_P(p) PG_RETURN_POINTER(p)
|
||||
|
||||
#define jspIsScalar(type) ((type) >= jpiNull && (type) <= jpiBool)
|
||||
|
||||
/*
|
||||
* All node's type of jsonpath expression
|
||||
*/
|
||||
|
|
|
@ -2731,6 +2731,114 @@ SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
|
|||
42
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
|
||||
count
|
||||
-------
|
||||
194
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
|
||||
count
|
||||
-------
|
||||
337
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
|
||||
count
|
||||
-------
|
||||
42
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
count
|
||||
-------
|
||||
194
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
CREATE INDEX jidx ON testjsonb USING gin (j);
|
||||
SET enable_seqscan = off;
|
||||
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
|
||||
|
@ -2806,6 +2914,196 @@ SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
|
|||
42
|
||||
(1 row)
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
QUERY PLAN
|
||||
-----------------------------------------------------------------
|
||||
Aggregate
|
||||
-> Bitmap Heap Scan on testjsonb
|
||||
Recheck Cond: (j @@ '($."wait" == null)'::jsonpath)
|
||||
-> Bitmap Index Scan on jidx
|
||||
Index Cond: (j @@ '($."wait" == null)'::jsonpath)
|
||||
(5 rows)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
|
||||
count
|
||||
-------
|
||||
194
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
|
||||
count
|
||||
-------
|
||||
337
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
|
||||
count
|
||||
-------
|
||||
42
|
||||
(1 row)
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------
|
||||
Aggregate
|
||||
-> Bitmap Heap Scan on testjsonb
|
||||
Recheck Cond: (j @? '$."wait"?(@ == null)'::jsonpath)
|
||||
-> Bitmap Index Scan on jidx
|
||||
Index Cond: (j @? '$."wait"?(@ == null)'::jsonpath)
|
||||
(5 rows)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
count
|
||||
-------
|
||||
194
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
-- array exists - array elements should behave as keys (for GIN index scans too)
|
||||
CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
|
||||
SELECT count(*) from testjsonb WHERE j->'array' ? 'bar';
|
||||
|
@ -2956,6 +3254,161 @@ SELECT count(*) FROM testjsonb WHERE j @> '{}';
|
|||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------------
|
||||
Aggregate
|
||||
-> Bitmap Heap Scan on testjsonb
|
||||
Recheck Cond: (j @? '$."wait"?(@ == null)'::jsonpath)
|
||||
-> Bitmap Index Scan on jidx
|
||||
Index Cond: (j @? '$."wait"?(@ == null)'::jsonpath)
|
||||
(5 rows)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
count
|
||||
-------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
count
|
||||
-------
|
||||
15
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
count
|
||||
-------
|
||||
2
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
|
||||
count
|
||||
-------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
count
|
||||
-------
|
||||
1012
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
count
|
||||
-------
|
||||
194
|
||||
(1 row)
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
count
|
||||
-------
|
||||
0
|
||||
(1 row)
|
||||
|
||||
RESET enable_seqscan;
|
||||
DROP INDEX jidx;
|
||||
-- nested tests
|
||||
|
|
|
@ -1920,6 +1920,8 @@ ORDER BY 1, 2, 3;
|
|||
2742 | 9 | ?
|
||||
2742 | 10 | ?|
|
||||
2742 | 11 | ?&
|
||||
2742 | 15 | @?
|
||||
2742 | 16 | @@
|
||||
3580 | 1 | <
|
||||
3580 | 1 | <<
|
||||
3580 | 2 | &<
|
||||
|
@ -1985,7 +1987,7 @@ ORDER BY 1, 2, 3;
|
|||
4000 | 26 | >>
|
||||
4000 | 27 | >>=
|
||||
4000 | 28 | ^@
|
||||
(123 rows)
|
||||
(125 rows)
|
||||
|
||||
-- Check that all opclass search operators have selectivity estimators.
|
||||
-- This is not absolutely required, but it seems a reasonable thing
|
||||
|
|
|
@ -740,6 +740,24 @@ SELECT count(*) FROM testjsonb WHERE j ? 'public';
|
|||
SELECT count(*) FROM testjsonb WHERE j ? 'bar';
|
||||
SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
|
||||
SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
|
||||
CREATE INDEX jidx ON testjsonb USING gin (j);
|
||||
SET enable_seqscan = off;
|
||||
|
@ -758,6 +776,39 @@ SELECT count(*) FROM testjsonb WHERE j ? 'bar';
|
|||
SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
|
||||
SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.bar)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) || exists($.disabled)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.public) && exists($.disabled)';
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
|
||||
-- array exists - array elements should behave as keys (for GIN index scans too)
|
||||
CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
|
||||
SELECT count(*) from testjsonb WHERE j->'array' ? 'bar';
|
||||
|
@ -807,6 +858,34 @@ SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
|
|||
-- exercise GIN_SEARCH_MODE_ALL
|
||||
SELECT count(*) FROM testjsonb WHERE j @> '{}';
|
||||
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == null';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.wait == null))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.wait ? (@ == null))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '"CC" == $.wait';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.wait == "CC" && true == $.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.age == 25.0';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "foo"';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ '$.array[*] == "bar"';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($ ? (@.array[*] == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array ? (@[*] == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($.array[*] ? (@ == "bar"))';
|
||||
SELECT count(*) FROM testjsonb WHERE j @@ 'exists($)';
|
||||
|
||||
EXPLAIN (COSTS OFF)
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? (@ == null)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.wait ? ("CC" == @)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.wait == "CC" && true == @.public)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.age ? (@ == 25)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.age == 25.0)';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$ ? (@.array[*] == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array ? (@[*] == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.array[*] ? (@ == "bar")';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.public';
|
||||
SELECT count(*) FROM testjsonb WHERE j @? '$.bar';
|
||||
|
||||
RESET enable_seqscan;
|
||||
DROP INDEX jidx;
|
||||
|
||||
|
|
|
@ -867,6 +867,7 @@ GinBtreeEntryInsertData
|
|||
GinBtreeStack
|
||||
GinBuildState
|
||||
GinChkVal
|
||||
GinEntries
|
||||
GinEntryAccumulator
|
||||
GinIndexStat
|
||||
GinMetaPageData
|
||||
|
@ -1106,6 +1107,13 @@ JsonPath
|
|||
JsonPathBool
|
||||
JsonPathExecContext
|
||||
JsonPathExecResult
|
||||
JsonPathGinAddPathItemFunc
|
||||
JsonPathGinContext
|
||||
JsonPathGinExtractNodesFunc
|
||||
JsonPathGinNode
|
||||
JsonPathGinNodeType
|
||||
JsonPathGinPath
|
||||
JsonPathGinPathItem
|
||||
JsonPathItem
|
||||
JsonPathItemType
|
||||
JsonPathParseItem
|
||||
|
|
Loading…
Reference in New Issue