Skip to content

Commit

Permalink
opt: index accelerate JSON filters in the forms j->'a' @> '1' and j->…
Browse files Browse the repository at this point in the history
…'a'<@'1'

We previously did not have inverted index support for expressions with a
JSON fetch val operator on the left side of @> (contains) or <@ (contained by)
expressions.

This commit adds support to use the inverted index for query filters with JSON
fetch val and containment operators. These include any contains or contained by
expressions with fetch val or chained fetch val operators on the left side, and
a constant value on the right side, including booleans, strings, numbers,
nulls, arrays, and objects.

Fixes #61430

Release note (performance improvement): Expressions with the -> (fetch val)
operator on the left side of either <@ (contained by) or @> (contains) now
support index-acceleration.
  • Loading branch information
angelazxu committed Apr 8, 2021
1 parent 3941029 commit eae73f2
Show file tree
Hide file tree
Showing 7 changed files with 1,506 additions and 70 deletions.
199 changes: 198 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/inverted_index
Original file line number Diff line number Diff line change
Expand Up @@ -767,7 +767,12 @@ INSERT INTO f VALUES
(25, '{"a": {"b": "c", "d": "e"}}'),
(26, '{"a": {"b": "c"}, "d": "e"}'),
(27, '[1, 2, {"b": "c"}]'),
(28, '[{"a": {"b": "c"}}, "d", "e"]')
(28, '[{"a": {"b": "c"}}, "d", "e"]'),
(29, '{"a": null}'),
(30, '{"a": [1, 2, null]}'),
(31, 'null'),
(32, '{}'),
(33, '[]')

query T
SELECT j FROM f@i WHERE j->'a' = '1' ORDER BY k
Expand Down Expand Up @@ -880,6 +885,198 @@ SELECT j FROM f@i WHERE j->'a' = '"b"' AND j->'c' = '[{"d": 1}, {"e": 2}]' ORDER
----
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

# Expressions with fetch val and containment operators use the inverted index.
query T
SELECT j FROM f@i WHERE j->'a' @> '"b"' ORDER BY k
----
{"a": ["b", "c", "d", "e"]}
{"a": ["b", "e", "c", "d"]}
{"a": "b", "x": ["c", "d", "e"]}
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

query T
SELECT j FROM f@i WHERE j->'a' <@ '"b"' ORDER BY k
----
{"a": "b", "x": ["c", "d", "e"]}
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

query T
SELECT j FROM f@i WHERE j->'a' @> 'null' ORDER BY k
----
{"a": null}
{"a": [1, 2, null]}

query T
SELECT j FROM f@i WHERE j->'a' <@ 'null' ORDER BY k
----
{"a": null}

query T
SELECT j FROM f@i WHERE j->'a' <@ '[]' ORDER BY k
----
{"a": []}

query T
SELECT j FROM f@i WHERE j->'a' <@ '{}' ORDER BY k
----
{"a": {}}

query T
SELECT j FROM f@i WHERE j->'a' @> '[]' ORDER BY k
----
{"a": [1, 2]}
{"a": []}
{"a": ["b", "c", "d", "e"]}
{"a": ["b", "e", "c", "d"]}
{"a": [1, 2, null]}

query T
SELECT j FROM f@i WHERE j->'a' @> '{}' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}
{"a": {"d": 2}}
{"a": {"b": [1, 2]}}
{"a": {"b": {"c": 1}}}
{"a": {"b": {"c": 1, "d": 2}}}
{"a": {"b": {"d": 2}}}
{"a": {"b": {"c": [1, 2]}}}
{"a": {"b": {"c": [1, 2, 3]}}}
{"a": {}}
{"a": {"b": "c"}}
{"a": {"b": ["c", "d", "e"]}}
{"a": {"b": "c", "d": "e"}}
{"a": {"b": "c"}, "d": "e"}

query T
SELECT j FROM f@i WHERE j->'a' <@ '{"b": [1, 2]}' ORDER BY k
----
{"a": {"b": [1, 2]}}
{"a": {}}

query T
SELECT j FROM f@i WHERE j->'a' <@ '{"b": {"c": [1, 2]}}' ORDER BY k
----
{"a": {"b": {"c": [1, 2]}}}
{"a": {}}

query T
SELECT j FROM f@i WHERE j->'a' @> '{"b": ["c"]}' ORDER BY k
----
{"a": {"b": ["c", "d", "e"]}}

query T
SELECT j FROM f@i WHERE j->'c' @> '[{"d": 1}]' ORDER BY k
----
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

# Expressions with chained fetch val and containment operators use the inverted
# index.
query T
SELECT j FROM f@i WHERE j->'a'->'b' <@ '1' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}

query T
SELECT j FROM f@i WHERE j->'a'->'b' @> '1' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}
{"a": {"b": [1, 2]}}

query T
SELECT j FROM f@i WHERE j->'a'->'b' @> '[1, 2]' ORDER BY k
----
{"a": {"b": [1, 2]}}

query T
SELECT j FROM f@i WHERE j->'a'->'b' <@ '[1, 2]' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}
{"a": {"b": [1, 2]}}

query T
SELECT j FROM f@i WHERE j->'a'->'b' @> '"c"' ORDER BY k
----
{"a": {"b": "c"}}
{"a": {"b": ["c", "d", "e"]}}
{"a": {"b": "c", "d": "e"}}
{"a": {"b": "c"}, "d": "e"}

# Expressions with fetch val on the right side should use the inverted index.
query T
SELECT j FROM f@i WHERE '"b"' <@ j->'a' ORDER BY k
----
{"a": ["b", "c", "d", "e"]}
{"a": ["b", "e", "c", "d"]}
{"a": "b", "x": ["c", "d", "e"]}
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

query T
SELECT j FROM f@i WHERE '[1, 2]' <@ j->'a'->'b' ORDER BY k
----
{"a": {"b": [1, 2]}}

query T
SELECT j FROM f@i WHERE '{"b": {"c": [1, 2]}}' <@ j->'a' ORDER BY k
----
{"a": {"b": {"c": [1, 2]}}}
{"a": {"b": {"c": [1, 2, 3]}}}

# Conjunctions of fetch val and containment expressions use the inverted index.
query T
SELECT j FROM f@i WHERE j->'a' @> '"b"' AND '["c"]' <@ j->'a' ORDER BY k
----
{"a": ["b", "c", "d", "e"]}
{"a": ["b", "e", "c", "d"]}

# query T
# SELECT j FROM f@i WHERE j->'a' <@ '{"b": [1, 2]}' AND j->'a'->'b' @> '[1]' ORDER BY k
# ----

# query T
# SELECT j FROM f@i WHERE j->'a' @> '"b"' AND j->'a' <@ '["b", "c", "d", "e"]' ORDER BY k
# ----

query T
SELECT j FROM f@i WHERE j->'a' @> '{"d": 2}' AND '[1, 2]' @> j->'a'->'b' ORDER BY k
----
{"a": {"b": 1, "d": 2}}

# Disjunctions of fetch val and containment expressions use the inverted index.
query T
SELECT j FROM f@i WHERE j->'a' @> '[1, 2]' OR j->'a'->'b' @> '[1, 2]' ORDER BY k
----
{"a": [1, 2]}
{"a": {"b": [1, 2]}}
{"a": [1, 2, null]}

query T
SELECT j FROM f@i WHERE j->'a' @> '"b"' OR j->'a'->'b' <@ '[1, 2]' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}
{"a": {"b": [1, 2]}}
{"a": ["b", "c", "d", "e"]}
{"a": ["b", "e", "c", "d"]}
{"a": "b", "x": ["c", "d", "e"]}
{"a": "b", "c": [{"d": 1}, {"e": 2}]}

query T
SELECT j FROM f@i WHERE j->'a'->'b' <@ '{"c": [1, 2], "d": 2}' OR j->'a'->'b' <@ '["c", "d", "e", 1, 2, 3]' ORDER BY k
----
{"a": {"b": 1}}
{"a": {"b": 1, "d": 2}}
{"a": {"b": [1, 2]}}
{"a": {"b": {"d": 2}}}
{"a": {"b": {"c": [1, 2]}}}
{"a": {"b": "c"}}
{"a": {"b": ["c", "d", "e"]}}
{"a": {"b": "c", "d": "e"}}
{"a": {"b": "c"}, "d": "e"}

subtest arrays

statement ok
Expand Down
Loading

0 comments on commit eae73f2

Please sign in to comment.