From f93a42e2ba21be35262bb5dacd130ec473570fa4 Mon Sep 17 00:00:00 2001 From: Shivam Saraf Date: Mon, 10 Apr 2023 18:15:35 -0400 Subject: [PATCH] opt: inverted-index accelerate filters of the form j = ... and j IN (...) An inverted index can be used to accelerate queries, using the = and the IN operator, with filters having the fetch value operator present; eg: j->0 = '{"b": "c"}' and j->0 IN ('1', '2') where j is a JSON column. This has been done completed here: JSON column using the IN and the `=` operator without the fetch val operator (`->`). This PR aims to add support to generate inverted spans for queries not involving the fetch val operator and having the `=` operator or the `IN` operator. This was done by creating JSON objects from the JSON values present on the right side of the equality or the IN expression. Moreover, in this case, no "keys" were extracted from the left hand side of the operators while creating these JSON objects which were useful for creating the inverted spans. Epic: CRDB-3301 Fixes: #96658 Release note (performance improvement): The optimizer now plans inverted index scans for queries that do not use the JSON fetch value operator (`->`) alongside the `IN` and the `=` operators. eg: json_col = '{"b": "c"}' OR json_col IN ('"a"', '1') --- .../testdata/logic_test/inverted_index | 91 +++ .../exec/execbuilder/testdata/inverted_index | 564 ++++++++++++++++++ pkg/sql/opt/invertedidx/json_array.go | 64 +- pkg/sql/opt/invertedidx/json_array_test.go | 98 +++ pkg/sql/opt/xform/testdata/rules/select | 480 ++++++++++++++- 5 files changed, 1282 insertions(+), 15 deletions(-) diff --git a/pkg/sql/logictest/testdata/logic_test/inverted_index b/pkg/sql/logictest/testdata/logic_test/inverted_index index 81b3a410b980..46cbeeb69bfe 100644 --- a/pkg/sql/logictest/testdata/logic_test/inverted_index +++ b/pkg/sql/logictest/testdata/logic_test/inverted_index @@ -812,6 +812,97 @@ INSERT INTO f VALUES (42, '{"a": "a"}'), (43, '[[0, 1, 2], [0, 1, 2], "s"]') +# Testing the equality operator without the fetch value +# operator on an inverted index. + +query T +SELECT j FROM f@i WHERE j = '[[0, 1, 2]]' ORDER BY k +---- +[[0, 1, 2]] + +query T +SELECT j FROM f@i WHERE j = '{"a": "a"}' ORDER BY k +---- +{"a": "a"} + +query T +SELECT j FROM f@i WHERE j = '{"a": "a"}' ORDER BY k +---- +{"a": "a"} + +query T +SELECT j FROM f@i WHERE j = '{"b": 2, "a": 1}' ORDER BY k +---- +{"a": 1, "b": 2} + +query T +SELECT j FROM f@i WHERE j = '{"a": {"b": "c"}, "d": "e"}' ORDER BY k +---- +{"a": {"b": "c"}, "d": "e"} + +query T +SELECT j FROM f@i WHERE j = 'null' ORDER BY k +---- +null + +query T +SELECT j FROM f@i WHERE j = '[]' ORDER BY k +---- +[] + +query T +SELECT j FROM f@i WHERE j = '{}' ORDER BY k +---- +{} + +query T +SELECT j FROM f@i WHERE j = '1' ORDER BY k +---- + +query T +SELECT j FROM f@i WHERE j = '[[]]' ORDER BY k +---- +[[]] + +query T +SELECT j FROM f@i WHERE j = '[[0, 1, 2], [0, 1, 2], "s"]' ORDER BY k +---- +[[0, 1, 2], [0, 1, 2], "s"] + +# Testing the IN operator without the fetch value operator on +# an inverted index. + +query T +SELECT j FROM f@i WHERE j IN ('{}', '[]', 'null') ORDER BY k +---- +null +{} +[] + +query T +SELECT j FROM f@i WHERE j IN ('[1]') ORDER BY k +---- + +query T +SELECT j FROM f@i WHERE j IN ('{"a": "b", "x": ["c", "d", "e"]}', '{}') ORDER BY k +---- +{"a": "b", "x": ["c", "d", "e"]} +{} + +query T +SELECT j FROM f@i WHERE j IN ('{"a": []}', '{"a": {}}') ORDER BY k +---- +{"a": []} +{"a": {}} + +query T +SELECT j FROM f@i WHERE j IN ('{"a": [1, 2, null]}', '[[]]', '[[{"a": {"b": []}}]]') +ORDER BY k +---- +{"a": [1, 2, null]} +[[]] +[[{"a": {"b": []}}]] + query T SELECT j FROM f@i WHERE j->0 @> '[0, 1, 2, 3]' ORDER BY k ---- diff --git a/pkg/sql/opt/exec/execbuilder/testdata/inverted_index b/pkg/sql/opt/exec/execbuilder/testdata/inverted_index index 1af46468f878..6fd8b6869a20 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/inverted_index +++ b/pkg/sql/opt/exec/execbuilder/testdata/inverted_index @@ -2049,6 +2049,570 @@ vectorized: true table: d@foo_inv spans: /"a"/Arr/Arr/"a"-/"a"/Arr/Arr/"a"/PrefixEnd /"a"/Arr/Arr/"b"-/"a"/Arr/Arr/"b"/PrefixEnd /"a"/Arr/Arr/0-/"a"/Arr/Arr/0/PrefixEnd /"a"/Arr/Arr/1-/"a"/Arr/Arr/1/PrefixEnd +# Testing the equality operator without the fetch value +# operator on an inverted index. + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '[[0, 1, 2]]' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '[[0, 1, 2]]' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '{"a": "a"}' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '{"a": "a"}' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • scan + columns: (a) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /"a"/"a"-/"a"/"a"/PrefixEnd + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '[1]' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '[1]' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • scan + columns: (a) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /Arr/1-/Arr/1/PrefixEnd + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '[1,2]' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '[1, 2]' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = 'null' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = 'null' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • scan + columns: (a) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /NULL-/!NULL /Arr/NULL-/Arr/!NULL + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '{}' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '{}' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 2 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /{}-/{}/PrefixEnd /???-/[] + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '[]' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '[]' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 2 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /[]-/{} /???-/??? + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '{"b": 2, "a": 1}' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '{"a": 1, "b": 2}' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '{"a": {"b": "c"}, "d": "e"}' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '{"a": {"b": "c"}, "d": "e"}' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '1' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '1' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • scan + columns: (a) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /1-/1/PrefixEnd /Arr/1-/Arr/1/PrefixEnd + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '"a"' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ filter: b = '"a"' + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • scan + columns: (a) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /"a"-/"a"/PrefixEnd /Arr/"a"-/Arr/"a"/PrefixEnd + + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b = '[[0, 1, 2], [0, 1, 2], "s"]' +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '[[0, 1, 2], [0, 1, 2], "s"]' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column + + +# Testing the IN operator without the fetch value operator on an +# inverted index. + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('"a"', '"b"', '"c"') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 30 (missing stats) + │ filter: b IN ('"a"', '"b"', '"c"') + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 6 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /"a"-/"a"/PrefixEnd /"b"-/"b"/PrefixEnd /"c"-/"c"/PrefixEnd /Arr/"a"-/Arr/"a"/PrefixEnd /Arr/"b"-/Arr/"b"/PrefixEnd /Arr/"c"-/Arr/"c"/PrefixEnd + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('1', '2') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 20 (missing stats) + │ filter: b IN ('1', '2') + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 4 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /1-/1/PrefixEnd /2-/2/PrefixEnd /Arr/1-/Arr/1/PrefixEnd /Arr/2-/Arr/2/PrefixEnd + + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('[1, 2, 3]', '[1]', '[]') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 30 (missing stats) + │ filter: b IN ('[]', '[1]', '[1, 2, 3]') + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 2 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /[]-/{} /???-/??? + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('[1, 2, 3]', '[1]') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 20 (missing stats) + │ filter: b IN ('[1]', '[1, 2, 3]') + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 3 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /Arr/1-/Arr/1/PrefixEnd /Arr/2-/Arr/2/PrefixEnd /Arr/3-/Arr/3/PrefixEnd + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('{"a": []}', '{"a": {}}') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • filter + │ columns: (a, b) + │ estimated row count: 20 (missing stats) + │ filter: b IN ('{"a": []}', '{"a": {}}') + │ + └── • index join + │ columns: (a, b) + │ estimated row count: 111 (missing stats) + │ table: d@d_pkey + │ key columns: a + │ + └── • project + │ columns: (a) + │ + └── • inverted filter + │ columns: (a, b_inverted_key) + │ estimated row count: 111 (missing stats) + │ inverted column: b_inverted_key + │ num spans: 3 + │ + └── • scan + columns: (a, b_inverted_key) + estimated row count: 111 (missing stats) + table: d@foo_inv + spans: /"a"/[]-/"a"/{}/PrefixEnd /???-/??? /???-/??? + + +query T +EXPLAIN (VERBOSE) SELECT a FROM d WHERE b IN ('[[0, 1, 2], [0, 1, 2], "s"]') +---- +distribution: local +vectorized: true +· +• project +│ columns: (a) +│ +└── • lookup join (inner) + │ columns: (a, b) + │ estimated row count: 10 (missing stats) + │ table: d@d_pkey + │ equality: (a) = (a) + │ equality cols are key + │ pred: b = '[[0, 1, 2], [0, 1, 2], "s"]' + │ + └── • project + │ columns: (a) + │ + └── • zigzag join + columns: (a, b_inverted_key, a, b_inverted_key) + estimated row count: 12 (missing stats) + left table: d@foo_inv + left columns: (a, b_inverted_key) + left fixed values: 1 column + right table: d@foo_inv + right columns: (a, b_inverted_key) + right fixed values: 1 column # Stats reflect the following, with some histogram buckets removed: # insert into d select g, '[1,2]' from generate_series(1,1000) g(g); diff --git a/pkg/sql/opt/invertedidx/json_array.go b/pkg/sql/opt/invertedidx/json_array.go index ce12ddc3cc08..233f33992029 100644 --- a/pkg/sql/opt/invertedidx/json_array.go +++ b/pkg/sql/opt/invertedidx/json_array.go @@ -391,12 +391,12 @@ func (j *jsonOrArrayFilterPlanner) extractInvertedFilterConditionFromLeaf( case *memo.EqExpr: if fetch, ok := t.Left.(*memo.FetchValExpr); ok { invertedExpr = j.extractJSONFetchValEqCondition(ctx, evalCtx, fetch, t.Right) + } else if fetch, ok := t.Left.(*memo.VariableExpr); ok { + invertedExpr = j.extractJSONEqCondition(ctx, evalCtx, fetch, t.Right) } case *memo.InExpr: - if fetch, ok := t.Left.(*memo.FetchValExpr); ok { - if tuple, ok := t.Right.(*memo.TupleExpr); ok { - invertedExpr = j.extractJSONInCondition(ctx, evalCtx, fetch, tuple) - } + if tuple, ok := t.Right.(*memo.TupleExpr); ok { + invertedExpr = j.extractJSONInCondition(ctx, evalCtx, t.Left, tuple) } case *memo.OverlapsExpr: invertedExpr = j.extractArrayOverlapsCondition(ctx, evalCtx, t.Left, t.Right) @@ -424,16 +424,32 @@ func (j *jsonOrArrayFilterPlanner) extractInvertedFilterConditionFromLeaf( // InvertedExpression cannot be generated from the expression, an // inverted.NonInvertedColExpression is returned. func (j *jsonOrArrayFilterPlanner) extractJSONInCondition( - ctx context.Context, evalCtx *eval.Context, left *memo.FetchValExpr, right *memo.TupleExpr, + ctx context.Context, evalCtx *eval.Context, left opt.ScalarExpr, right *memo.TupleExpr, ) inverted.Expression { + + fetch := false + switch left.(type) { + case *memo.FetchValExpr: + fetch = true + case *memo.VariableExpr: + fetch = false + default: + return nil + } + // The right side of the expression should be a constant JSON value. if !memo.CanExtractConstDatum(right) { return inverted.NonInvertedColExpression{} } var invertedExpr inverted.Expression + var expr inverted.Expression for i := range right.Elems { scalarExprElem := right.Elems[i] - expr := j.extractJSONFetchValEqCondition(ctx, evalCtx, left, scalarExprElem) + if fetch { + expr = j.extractJSONFetchValEqCondition(ctx, evalCtx, left.(*memo.FetchValExpr), scalarExprElem) + } else { + expr = j.extractJSONEqCondition(ctx, evalCtx, left.(*memo.VariableExpr), scalarExprElem) + } if invertedExpr == nil { invertedExpr = expr } else { @@ -543,6 +559,42 @@ func (j *jsonOrArrayFilterPlanner) extractJSONExistsCondition( return inverted.NonInvertedColExpression{} } +// extractJSONFetchValEqCondition extracts an InvertedExpression representing an +// inverted filter over the planner's inverted index, based on equality between +// two scalar expressions. If an InvertedExpression cannot be generated from the +// expression, an inverted.NonInvertedColExpression is returned. This is different +// from extractJSONFetchValEqCondition since no fetch val operators exist when +// checking for equality. +func (j *jsonOrArrayFilterPlanner) extractJSONEqCondition( + ctx context.Context, evalCtx *eval.Context, left *memo.VariableExpr, right opt.ScalarExpr, +) inverted.Expression { + // The right side of the expression should be a constant JSON value. + if !memo.CanExtractConstDatum(right) { + return inverted.NonInvertedColExpression{} + } + val, ok := memo.ExtractConstDatum(right).(*tree.DJSON) + if !ok { + return inverted.NonInvertedColExpression{} + } + + // For Equals expressions, we will generate the inverted expression for the + // single object built from the keys and val. + invertedExpr := getInvertedExprForJSONOrArrayIndexForContaining(ctx, evalCtx, val) + + // Generated inverted expression won't be tight as we are searching for rows + // inside of the index consisting of a particular JSON value. Since the exact + // position of this value is not specified, the generated expression is not tight. + // + // For example, consider a filter of the form: j = '1' where j is a JSON column + // on which an inverted index is constructed. Other entries inside of this + // index, such as JSON arrays and objects, may consist of the element 1 present + // within them. Since the encodings inside the index do not contain the position + // of their elements, the generated inverted expressions are not tight. + invertedExpr.SetNotTight() + + return invertedExpr +} + // extractJSONFetchValEqCondition extracts an InvertedExpression representing an // inverted filter over the planner's inverted index, based on equality between // a chain of fetch val expressions and a scalar expression. If an diff --git a/pkg/sql/opt/invertedidx/json_array_test.go b/pkg/sql/opt/invertedidx/json_array_test.go index 60b9095c6feb..cc70035e2acc 100644 --- a/pkg/sql/opt/invertedidx/json_array_test.go +++ b/pkg/sql/opt/invertedidx/json_array_test.go @@ -1031,6 +1031,104 @@ func TestTryFilterJsonOrArrayIndex(t *testing.T) { tight: false, unique: false, }, + { + // Testing the equality operator without the fetch value operator. + filters: `j = '1'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j = '1'`, + }, + { + filters: `j = '"a"'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j = '"a"'`, + }, + { + filters: `j = '[1, 2, 3, 4]'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j = '[1, 2, 3, 4]'`, + }, + { + filters: `j = '[1]'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j = '[1]'`, + }, + { + filters: `j = '{"a": "b"}'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j = '{"a": "b"}'`, + }, + { + filters: `j = '{"a": "b"}' OR j = '[1, 2, 3]'`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j = '{"a": "b"}' OR j = '[1, 2, 3]'`, + }, + { + // Testing the IN operator without the fetch value operator. + filters: `j IN ('1', '2', '3')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j IN ('1', '2', '3')`, + }, + { + filters: `j IN ('"a"', '"b"', '"c"')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j IN ('"a"', '"b"', '"c"')`, + }, + { + filters: `j IN ('1', '"b"', '[1, 2, 3]')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j IN ('1', '"b"', '[1, 2, 3]')`, + }, + { + filters: `j IN ('[1, 2, 3]')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: true, + remainingFilters: `j IN ('[1, 2, 3]')`, + }, + { + filters: `j IN ('[1, 2, 3]', '{"a": "b"}')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j IN ('[1, 2, 3]', '{"a": "b"}')`, + }, + { + filters: `j IN ('[1, 2, 3]', '{"a": "b"}', '1', '"a"')`, + indexOrd: jsonOrd, + ok: true, + tight: false, + unique: false, + remainingFilters: `j IN ('[1, 2, 3]', '{"a": "b"}', '1', '"a"')`, + }, } for _, tc := range testCases { diff --git a/pkg/sql/opt/xform/testdata/rules/select b/pkg/sql/opt/xform/testdata/rules/select index c69c8760c26c..8805121dac52 100644 --- a/pkg/sql/opt/xform/testdata/rules/select +++ b/pkg/sql/opt/xform/testdata/rules/select @@ -2777,8 +2777,41 @@ select ├── j:4 <@ '{"a": [3]}' [outer=(4), immutable] └── j:4 <@ '[1, 2, 3]' [outer=(4), immutable] -# Query not using the fetch val but using the equality operator. -opt expect-not=GenerateInvertedIndexScans +# Testing the equality operator, without the fetch val operator, +# on an inverted index. In all such cases, the inverted expression +# generated is not tight resulting in the original filter to be +# applied again. + + +# Testing equality for a JSON null on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = 'null' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01\x00", "7\x00\x01\x00"] + │ │ └── ["7\x00\x03\x00\x01\x00", "7\x00\x03\x00\x01\x00"] + │ └── key: (1) + └── filters + └── j:4 = 'null' [outer=(4), immutable, constraints=(/4: [/'null' - /'null']; tight), fd=()-->(4)] + +# Testing equality for a JSON string on an inverted index. +opt expect=GenerateInvertedIndexScans SELECT k FROM b WHERE j = '"b"' ---- project @@ -2790,13 +2823,195 @@ project ├── immutable ├── key: (1) ├── fd: ()-->(4) - ├── scan b + ├── index-join b │ ├── columns: k:1!null j:4 │ ├── key: (1) - │ └── fd: (1)-->(4) + │ ├── fd: (1)-->(4) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01\x12b\x00\x01", "7\x00\x01\x12b\x00\x01"] + │ │ └── ["7\x00\x03\x00\x01\x12b\x00\x01", "7\x00\x03\x00\x01\x12b\x00\x01"] + │ └── key: (1) └── filters └── j:4 = '"b"' [outer=(4), immutable, constraints=(/4: [/'"b"' - /'"b"']; tight), fd=()-->(4)] +# Testing equality for a JSON number on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '1' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01*\x02\x00", "7\x00\x01*\x02\x00"] + │ │ └── ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ └── key: (1) + └── filters + └── j:4 = '1' [outer=(4), immutable, constraints=(/4: [/'1' - /'1']; tight), fd=()-->(4)] + +# Testing equality for a JSON empty string on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '""' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01\x12\x00\x01", "7\x00\x01\x12\x00\x01"] + │ │ └── ["7\x00\x03\x00\x01\x12\x00\x01", "7\x00\x03\x00\x01\x12\x00\x01"] + │ └── key: (1) + └── filters + └── j:4 = '""' [outer=(4), immutable, constraints=(/4: [/'""' - /'""']; tight), fd=()-->(4)] + +# Testing equality for a JSON array on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '[1, 2, 3]' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── inner-join (lookup b) + ├── columns: k:1!null j:4!null + ├── key columns: [1] = [1] + ├── lookup columns are key + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── inner-join (zigzag b@j_inv_idx b@j_inv_idx) + │ ├── columns: k:1!null + │ ├── eq columns: [1] = [1] + │ ├── left fixed columns: [7] = ['\x37000300012a0200'] + │ ├── right fixed columns: [7] = ['\x37000300012a0400'] + │ └── filters (true) + └── filters + └── j:4 = '[1, 2, 3]' [outer=(4), immutable, constraints=(/4: [/'[1, 2, 3]' - /'[1, 2, 3]']; tight), fd=()-->(4)] + + +# Testing equality for a JSON empty array on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '[]' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ └── union spans + │ │ ├── ["7\x00\x018", "7\x00\x018"] + │ │ └── ["7\x00\x03", "7\x00\x03"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x018", "7\x00\x018"] + │ │ └── ["7\x00\x03", "7\x00\x03"] + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 = '[]' [outer=(4), immutable, constraints=(/4: [/'[]' - /'[]']; tight), fd=()-->(4)] + +# Testing equality for a JSON empty object on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '{}' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ └── union spans + │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ └── ["7\x00\xff", "8") + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ └── ["7\x00\xff", "8") + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 = '{}' [outer=(4), immutable, constraints=(/4: [/'{}' - /'{}']; tight), fd=()-->(4)] + +# Testing equality for a JSON object on an inverted index. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j = '{"a": "b", "c": "d"}' +---- +project + ├── columns: k:1!null + ├── immutable + ├── key: (1) + └── inner-join (lookup b) + ├── columns: k:1!null j:4!null + ├── key columns: [1] = [1] + ├── lookup columns are key + ├── immutable + ├── key: (1) + ├── fd: ()-->(4) + ├── inner-join (zigzag b@j_inv_idx b@j_inv_idx) + │ ├── columns: k:1!null + │ ├── eq columns: [1] = [1] + │ ├── left fixed columns: [7] = ['\x3761000112620001'] + │ ├── right fixed columns: [7] = ['\x3763000112640001'] + │ └── filters (true) + └── filters + └── j:4 = '{"a": "b", "c": "d"}' [outer=(4), immutable, constraints=(/4: [/'{"a": "b", "c": "d"}' - /'{"a": "b", "c": "d"}']; tight), fd=()-->(4)] + # Query using the fetch val and equality operators. opt expect=GenerateInvertedIndexScans SELECT k FROM b WHERE j->'a' = '"b"' @@ -3373,9 +3588,11 @@ project └── fd: (1)-->(7) -# Query NOT using the fetch val and the IN operator. -# This should result in a full table scan (at the moment) -opt expect-not=GenerateInvertedIndexScans +# Testing the IN operator, without the fetch val operator, +# on an inverted index. + +# Multiple JSON numbers contained within the IN operator. +opt expect=GenerateInvertedIndexScans SELECT k FROM b WHERE j IN ('1', '2', '3') ---- project @@ -3385,13 +3602,258 @@ project ├── columns: k:1!null j:4!null ├── key: (1) ├── fd: (1)-->(4) - ├── scan b + ├── index-join b │ ├── columns: k:1!null j:4 │ ├── key: (1) - │ └── fd: (1)-->(4) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ └── union spans + │ │ ├── ["7\x00\x01*\x02\x00", "7\x00\x01*\x02\x00"] + │ │ ├── ["7\x00\x01*\x04\x00", "7\x00\x01*\x04\x00"] + │ │ ├── ["7\x00\x01*\x06\x00", "7\x00\x01*\x06\x00"] + │ │ ├── ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ ├── ["7\x00\x03\x00\x01*\x04\x00", "7\x00\x03\x00\x01*\x04\x00"] + │ │ └── ["7\x00\x03\x00\x01*\x06\x00", "7\x00\x03\x00\x01*\x06\x00"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01*\x02\x00", "7\x00\x01*\x02\x00"] + │ │ ├── ["7\x00\x01*\x04\x00", "7\x00\x01*\x04\x00"] + │ │ ├── ["7\x00\x01*\x06\x00", "7\x00\x01*\x06\x00"] + │ │ ├── ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ ├── ["7\x00\x03\x00\x01*\x04\x00", "7\x00\x03\x00\x01*\x04\x00"] + │ │ └── ["7\x00\x03\x00\x01*\x06\x00", "7\x00\x03\x00\x01*\x06\x00"] + │ ├── key: (1) + │ └── fd: (1)-->(7) └── filters └── j:4 IN ('1', '2', '3') [outer=(4), constraints=(/4: [/'1' - /'1'] [/'2' - /'2'] [/'3' - /'3']; tight)] + +# Multiple JSON strings contained within the IN operator. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j IN ('"a"', '"b"', '"c"') +---- +project + ├── columns: k:1!null + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── key: (1) + ├── fd: (1)-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ └── union spans + │ │ ├── ["7\x00\x01\x12a\x00\x01", "7\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x01\x12b\x00\x01", "7\x00\x01\x12b\x00\x01"] + │ │ ├── ["7\x00\x01\x12c\x00\x01", "7\x00\x01\x12c\x00\x01"] + │ │ ├── ["7\x00\x03\x00\x01\x12a\x00\x01", "7\x00\x03\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x03\x00\x01\x12b\x00\x01", "7\x00\x03\x00\x01\x12b\x00\x01"] + │ │ └── ["7\x00\x03\x00\x01\x12c\x00\x01", "7\x00\x03\x00\x01\x12c\x00\x01"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01\x12a\x00\x01", "7\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x01\x12b\x00\x01", "7\x00\x01\x12b\x00\x01"] + │ │ ├── ["7\x00\x01\x12c\x00\x01", "7\x00\x01\x12c\x00\x01"] + │ │ ├── ["7\x00\x03\x00\x01\x12a\x00\x01", "7\x00\x03\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x03\x00\x01\x12b\x00\x01", "7\x00\x03\x00\x01\x12b\x00\x01"] + │ │ └── ["7\x00\x03\x00\x01\x12c\x00\x01", "7\x00\x03\x00\x01\x12c\x00\x01"] + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 IN ('"a"', '"b"', '"c"') [outer=(4), constraints=(/4: [/'"a"' - /'"a"'] [/'"b"' - /'"b"'] [/'"c"' - /'"c"']; tight)] + + +# Multiple JSON arrays contained within the IN operator. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j IN ('[1, 2, 3]', '[1, 2]', '[1]', '[]') +---- +project + ├── columns: k:1!null + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── key: (1) + ├── fd: (1)-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ ├── union spans + │ │ │ ├── ["7\x00\x018", "7\x00\x018"] + │ │ │ └── ["7\x00\x03", "7\x00\x03"] + │ │ └── UNION + │ │ ├── span expression + │ │ │ ├── tight: false, unique: false + │ │ │ ├── union spans: empty + │ │ │ └── INTERSECTION + │ │ │ ├── span expression + │ │ │ │ ├── tight: true, unique: true + │ │ │ │ └── union spans: ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ │ └── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ └── union spans: ["7\x00\x03\x00\x01*\x04\x00", "7\x00\x03\x00\x01*\x04\x00"] + │ │ └── span expression + │ │ ├── tight: false, unique: true + │ │ ├── union spans: empty + │ │ └── INTERSECTION + │ │ ├── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ ├── union spans: empty + │ │ │ └── INTERSECTION + │ │ │ ├── span expression + │ │ │ │ ├── tight: true, unique: true + │ │ │ │ └── union spans: ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ │ └── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ └── union spans: ["7\x00\x03\x00\x01*\x04\x00", "7\x00\x03\x00\x01*\x04\x00"] + │ │ └── span expression + │ │ ├── tight: true, unique: true + │ │ └── union spans: ["7\x00\x03\x00\x01*\x06\x00", "7\x00\x03\x00\x01*\x06\x00"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x018", "7\x00\x018"] + │ │ └── ["7\x00\x03", "7\x00\x03"] + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 IN ('[]', '[1]', '[1, 2]', '[1, 2, 3]') [outer=(4), constraints=(/4: [/'[]' - /'[]'] [/'[1]' - /'[1]'] [/'[1, 2]' - /'[1, 2]'] [/'[1, 2, 3]' - /'[1, 2, 3]']; tight)] + +# Multiple JSON objects contained within the IN operator. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j IN ('{"a": "b", "c": "d"}', '{}', '{"a": [1, 2, 3]}') +---- +project + ├── columns: k:1!null + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── key: (1) + ├── fd: (1)-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ ├── union spans + │ │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ │ └── ["7\x00\xff", "8") + │ │ └── UNION + │ │ ├── span expression + │ │ │ ├── tight: false, unique: false + │ │ │ ├── union spans: empty + │ │ │ └── INTERSECTION + │ │ │ ├── span expression + │ │ │ │ ├── tight: true, unique: true + │ │ │ │ ├── union spans: empty + │ │ │ │ └── INTERSECTION + │ │ │ │ ├── span expression + │ │ │ │ │ ├── tight: true, unique: true + │ │ │ │ │ └── union spans: ["7a\x00\x02\x00\x03\x00\x01*\x02\x00", "7a\x00\x02\x00\x03\x00\x01*\x02\x00"] + │ │ │ │ └── span expression + │ │ │ │ ├── tight: true, unique: true + │ │ │ │ └── union spans: ["7a\x00\x02\x00\x03\x00\x01*\x04\x00", "7a\x00\x02\x00\x03\x00\x01*\x04\x00"] + │ │ │ └── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ └── union spans: ["7a\x00\x02\x00\x03\x00\x01*\x06\x00", "7a\x00\x02\x00\x03\x00\x01*\x06\x00"] + │ │ └── span expression + │ │ ├── tight: false, unique: true + │ │ ├── union spans: empty + │ │ └── INTERSECTION + │ │ ├── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ └── union spans: ["7a\x00\x01\x12b\x00\x01", "7a\x00\x01\x12b\x00\x01"] + │ │ └── span expression + │ │ ├── tight: true, unique: true + │ │ └── union spans: ["7c\x00\x01\x12d\x00\x01", "7c\x00\x01\x12d\x00\x01"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ └── ["7\x00\xff", "8") + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 IN ('{}', '{"a": [1, 2, 3]}', '{"a": "b", "c": "d"}') [outer=(4), constraints=(/4: [/'{}' - /'{}'] [/'{"a": [1, 2, 3]}' - /'{"a": [1, 2, 3]}'] [/'{"a": "b", "c": "d"}' - /'{"a": "b", "c": "d"}']; tight)] + +# Combination of JSON values contained within the IN operator. +opt expect=GenerateInvertedIndexScans +SELECT k FROM b WHERE j IN ('{"a": "b", "c": "d"}', '{}', 'null', '1', '"a"') +---- +project + ├── columns: k:1!null + ├── key: (1) + └── select + ├── columns: k:1!null j:4!null + ├── key: (1) + ├── fd: (1)-->(4) + ├── index-join b + │ ├── columns: k:1!null j:4 + │ ├── key: (1) + │ ├── fd: (1)-->(4) + │ └── inverted-filter + │ ├── columns: k:1!null + │ ├── inverted expression: /7 + │ │ ├── tight: false, unique: false + │ │ ├── union spans + │ │ │ ├── ["7\x00\x01\x00", "7\x00\x01\x00"] + │ │ │ ├── ["7\x00\x01\x12a\x00\x01", "7\x00\x01\x12a\x00\x01"] + │ │ │ ├── ["7\x00\x01*\x02\x00", "7\x00\x01*\x02\x00"] + │ │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ │ ├── ["7\x00\x03\x00\x01\x00", "7\x00\x03\x00\x01\x00"] + │ │ │ ├── ["7\x00\x03\x00\x01\x12a\x00\x01", "7\x00\x03\x00\x01\x12a\x00\x01"] + │ │ │ ├── ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ │ └── ["7\x00\xff", "8") + │ │ └── INTERSECTION + │ │ ├── span expression + │ │ │ ├── tight: true, unique: true + │ │ │ └── union spans: ["7a\x00\x01\x12b\x00\x01", "7a\x00\x01\x12b\x00\x01"] + │ │ └── span expression + │ │ ├── tight: true, unique: true + │ │ └── union spans: ["7c\x00\x01\x12d\x00\x01", "7c\x00\x01\x12d\x00\x01"] + │ ├── key: (1) + │ └── scan b@j_inv_idx + │ ├── columns: k:1!null j_inverted_key:7!null + │ ├── inverted constraint: /7/1 + │ │ └── spans + │ │ ├── ["7\x00\x01\x00", "7\x00\x01\x00"] + │ │ ├── ["7\x00\x01\x12a\x00\x01", "7\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x01*\x02\x00", "7\x00\x01*\x02\x00"] + │ │ ├── ["7\x00\x019", "7\x00\x019"] + │ │ ├── ["7\x00\x03\x00\x01\x00", "7\x00\x03\x00\x01\x00"] + │ │ ├── ["7\x00\x03\x00\x01\x12a\x00\x01", "7\x00\x03\x00\x01\x12a\x00\x01"] + │ │ ├── ["7\x00\x03\x00\x01*\x02\x00", "7\x00\x03\x00\x01*\x02\x00"] + │ │ └── ["7\x00\xff", "8") + │ ├── key: (1) + │ └── fd: (1)-->(7) + └── filters + └── j:4 IN ('null', '"a"', '1', '{}', '{"a": "b", "c": "d"}') [outer=(4), constraints=(/4: [/'null' - /'null'] [/'"a"' - /'"a"'] [/'1' - /'1'] [/'{}' - /'{}'] [/'{"a": "b", "c": "d"}' - /'{"a": "b", "c": "d"}']; tight)] + # Generate an inverted scan when the index of the fetch val operator is # a string along with the IN operator consisting of JSON strings in # the tuple. Since the inverted expression is tight,