Skip to content

Commit

Permalink
opt: do not cross-join input of semi-join
Browse files Browse the repository at this point in the history
This commit fixes a logical correctness bug caused when
`GenerateLookupJoins` cross-joins the input of a semi-join with a set of
constant values to constrain the prefix columns of the lookup index. The
cross-join is an invalid transformation because it increases the size of
the join's input and can increase the size of the join's output.

We already avoid these cross-joins for left and anti-joins (see #59646).
When addressing those cases, the semi-join case was incorrectly assumed
to be safe.

Fixes #78681

Release note (bug fix): A bug has been fixed which caused the optimizer
to generate invalid query plans which could result in incorrect query
results. The bug, which has been present since version 21.1.0, can
appear under all of the following conditions: 1) the query contains a
semi-join, such as queries in the form:
`SELECT * FROM t WHERE EXISTS (SELECT * FROM t2 WHERE t.a = t2.a`)`;
2) the inner table had an index containing the equality column, like
`t2.a` in the example query; 3) the index contained one or more
columns that prefix the equality column; and 4) the prefix columns are
`NOT NULL` and are constrained to a set of constant values via a `CHECK`
constraint or an `IN` condition in the filter.
  • Loading branch information
mgartner committed Mar 28, 2022
1 parent c1e089d commit 68d87ef
Show file tree
Hide file tree
Showing 2 changed files with 35 additions and 29 deletions.
2 changes: 1 addition & 1 deletion pkg/sql/opt/xform/join_funcs.go
Original file line number Diff line number Diff line change
Expand Up @@ -456,7 +456,7 @@ func (c *CustomFuncs) generateLookupJoinsImpl(
}

if len(foundVals) > 1 {
if joinType == opt.LeftJoinOp || joinType == opt.AntiJoinOp {
if joinType == opt.LeftJoinOp || joinType == opt.SemiJoinOp || joinType == opt.AntiJoinOp {
// We cannot use the method constructJoinWithConstants to create a cross
// join for left or anti joins, because constructing a cross join with
// foundVals will increase the size of the input. As a result,
Expand Down
62 changes: 34 additions & 28 deletions pkg/sql/opt/xform/testdata/rules/join
Original file line number Diff line number Diff line change
Expand Up @@ -2834,8 +2834,8 @@ exec-ddl
DROP INDEX shard_b_null_idx
----

# Regression test for #59615. Ensure that invalid lookup joins are not created
# for left and anti joins.
# Regression test for #59615 and #78681. Ensure that invalid lookup joins are
# not created for left, semi, and anti joins.
exec-ddl
CREATE TABLE t59615 (
x INT NOT NULL CHECK (x in (1, 3)),
Expand Down Expand Up @@ -2863,6 +2863,26 @@ left-join (lookup t59615 [as=t])
│ └── (2,)
└── filters (true)

# Regression test for #78681.
opt expect=GenerateLookupJoins
SELECT * FROM (VALUES (1), (2)) AS u(y) WHERE EXISTS (
SELECT * FROM t59615 t WHERE u.y = t.y
)
----
semi-join (lookup t59615 [as=t])
├── columns: y:1!null
├── lookup expression
│ └── filters
│ ├── column1:1 = y:3 [outer=(1,3), constraints=(/1: (/NULL - ]; /3: (/NULL - ]), fd=(1)==(3), (3)==(1)]
│ └── x:2 IN (1, 3) [outer=(2), constraints=(/2: [/1 - /1] [/3 - /3]; tight)]
├── cardinality: [0 - 2]
├── values
│ ├── columns: column1:1!null
│ ├── cardinality: [2 - 2]
│ ├── (1,)
│ └── (2,)
└── filters (true)

opt expect=GenerateLookupJoins
SELECT * FROM (VALUES (1), (2)) AS u(y) WHERE NOT EXISTS (
SELECT * FROM t59615 t WHERE u.y = t.y
Expand Down Expand Up @@ -5095,20 +5115,13 @@ SELECT m FROM small WHERE EXISTS (SELECT * FROM virt WHERE m = virt.v1)
----
semi-join (lookup virt@j_v1)
├── columns: m:1
├── key columns: [16 1] = [8 9]
├── lookup expression
│ └── filters
│ ├── m:1 = v1:9 [outer=(1,9), constraints=(/1: (/NULL - ]; /9: (/NULL - ]), fd=(1)==(9), (9)==(1)]
│ └── j:8 IN (10, 20, 30) [outer=(8), constraints=(/8: [/10 - /10] [/20 - /20] [/30 - /30]; tight)]
├── immutable
├── inner-join (cross)
│ ├── columns: m:1 "lookup_join_const_col_@8":16!null
│ ├── multiplicity: left-rows(one-or-more), right-rows(zero-or-more)
│ ├── scan small
│ │ └── columns: m:1
│ ├── values
│ │ ├── columns: "lookup_join_const_col_@8":16!null
│ │ ├── cardinality: [3 - 3]
│ │ ├── (10,)
│ │ ├── (20,)
│ │ └── (30,)
│ └── filters (true)
├── scan small
│ └── columns: m:1
└── filters (true)

# Anti-join with multiple constant values based on optional filters.
Expand Down Expand Up @@ -5737,20 +5750,13 @@ SELECT m FROM small WHERE EXISTS (SELECT * FROM virt WHERE virt.l IN (1, 2, 3) A
----
semi-join (lookup virt@l_v1)
├── columns: m:1
├── key columns: [16 1] = [13 9]
├── lookup expression
│ └── filters
│ ├── m:1 = v1:9 [outer=(1,9), constraints=(/1: (/NULL - ]; /9: (/NULL - ]), fd=(1)==(9), (9)==(1)]
│ └── l:13 IN (1, 2, 3) [outer=(13), constraints=(/13: [/1 - /1] [/2 - /2] [/3 - /3]; tight)]
├── immutable
├── inner-join (cross)
│ ├── columns: m:1 "lookup_join_const_col_@13":16!null
│ ├── multiplicity: left-rows(one-or-more), right-rows(zero-or-more)
│ ├── scan small
│ │ └── columns: m:1
│ ├── values
│ │ ├── columns: "lookup_join_const_col_@13":16!null
│ │ ├── cardinality: [3 - 3]
│ │ ├── (1,)
│ │ ├── (2,)
│ │ └── (3,)
│ └── filters (true)
├── scan small
│ └── columns: m:1
└── filters (true)

# Semi-join with multiple constant values for the leading lookup column and a
Expand Down

0 comments on commit 68d87ef

Please sign in to comment.