From 66d88657f6a8bcdd026735f00282953c5daa16bb Mon Sep 17 00:00:00 2001 From: Marcus Gartner Date: Mon, 14 Feb 2022 15:58:57 -0500 Subject: [PATCH] opt: fix missing filters after join reordering This commit eliminates logic in the `assoc`, `leftAsscom`, and `rightAsscom` functions in the join order builder that aimed to prevent generating "orphaned" predicates, where one or more referenced relations are not in a join's input. In rare cases, this logic had the side effect of creating invalid conflict rules for edges, which could prevent valid predicates from being added to reordered join trees. It is safe to remove these conditionals because they are unnecessary. The CD-C algorithm already prevents generation of orphaned predicates by checking that the total eligibility set (TES) is a subset of a join's input vertices. In our implementation, this is handled by the `checkNonInnerJoin` and `checkInnerJoin` functions. Fixes #76522 Release note (bug fix): A bug has been fixed which caused the query optimizer to omit join filters in rare cases when reordering joins, which could result in incorrect query results. This bug was present since v20.2. --- pkg/sql/opt/exec/execbuilder/testdata/join | 195 +++++++++--------- pkg/sql/opt/xform/join_order_builder.go | 28 --- pkg/sql/opt/xform/join_order_builder_test.go | 16 ++ pkg/sql/opt/xform/testdata/external/tpce | 6 +- pkg/sql/opt/xform/testdata/rules/join_order | 202 ++++++++++++++++++- 5 files changed, 309 insertions(+), 138 deletions(-) diff --git a/pkg/sql/opt/exec/execbuilder/testdata/join b/pkg/sql/opt/exec/execbuilder/testdata/join index c7a95bb37df0..fb5c514209fd 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/join +++ b/pkg/sql/opt/exec/execbuilder/testdata/join @@ -431,120 +431,115 @@ vectorized: true │ render relname: relname │ └── • hash join (inner) - │ columns: (attrelid, attname, attnum, attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series, oid, relname, relnamespace, oid, nspname, objid, refobjid, oid, relname, relkind) + │ columns: (oid, nspname, oid, relname, relnamespace, attrelid, attname, attnum, attrelid, attname, attnum, objid, refobjid, oid, relname, relkind, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series) │ estimated row count: 110,908 (missing stats) - │ equality: (oid) = (objid) + │ equality: (oid) = (attrelid) │ ├── • hash join (inner) - │ │ columns: (attrelid, attname, attnum, attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series, oid, relname, relnamespace, oid, nspname) - │ │ estimated row count: 114,302 (missing stats) - │ │ equality: (relnamespace) = (oid) + │ │ columns: (oid, nspname, oid, relname, relnamespace) + │ │ estimated row count: 9,801 (missing stats) + │ │ equality: (oid) = (relnamespace) │ │ - │ ├── • hash join (inner) - │ │ │ columns: (attrelid, attname, attnum, attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series, oid, relname, relnamespace) - │ │ │ estimated row count: 11,557 (missing stats) - │ │ │ equality: (attrelid) = (oid) - │ │ │ pred: attnum = confkey[generate_series] - │ │ │ - │ │ ├── • hash join (inner) - │ │ │ │ columns: (attrelid, attname, attnum, attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series) - │ │ │ │ estimated row count: 3,502 (missing stats) - │ │ │ │ equality: (attrelid) = (confrelid) - │ │ │ │ - │ │ │ ├── • virtual table - │ │ │ │ columns: (attrelid, attname, attnum) - │ │ │ │ estimated row count: 1,000 (missing stats) - │ │ │ │ table: pg_attribute@primary - │ │ │ │ - │ │ │ └── • cross join (inner) - │ │ │ │ columns: (attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series) - │ │ │ │ estimated row count: 354 (missing stats) - │ │ │ │ pred: attnum = conkey[generate_series] - │ │ │ │ - │ │ │ ├── • hash join (inner) - │ │ │ │ │ columns: (attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname) - │ │ │ │ │ estimated row count: 107 (missing stats) - │ │ │ │ │ equality: (relnamespace) = (oid) - │ │ │ │ │ - │ │ │ │ ├── • merge join (inner) - │ │ │ │ │ │ columns: (attrelid, attname, attnum, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace) - │ │ │ │ │ │ estimated row count: 105 (missing stats) - │ │ │ │ │ │ equality: (attrelid) = (oid) - │ │ │ │ │ │ merge ordering: +"(attrelid=oid)" - │ │ │ │ │ │ - │ │ │ │ │ ├── • virtual table - │ │ │ │ │ │ columns: (attrelid, attname, attnum) - │ │ │ │ │ │ ordering: +attrelid - │ │ │ │ │ │ estimated row count: 1,000 (missing stats) - │ │ │ │ │ │ table: pg_attribute@pg_attribute_attrelid_idx - │ │ │ │ │ │ - │ │ │ │ │ └── • virtual table lookup join (inner) - │ │ │ │ │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace) - │ │ │ │ │ │ ordering: +conrelid - │ │ │ │ │ │ estimated row count: 10 (missing stats) - │ │ │ │ │ │ table: pg_class@pg_class_oid_idx - │ │ │ │ │ │ equality: (conrelid) = (oid) - │ │ │ │ │ │ pred: relname = 'orders' - │ │ │ │ │ │ - │ │ │ │ │ └── • filter - │ │ │ │ │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey) - │ │ │ │ │ │ ordering: +conrelid - │ │ │ │ │ │ estimated row count: 10 (missing stats) - │ │ │ │ │ │ filter: contype = 'f' - │ │ │ │ │ │ - │ │ │ │ │ └── • virtual table - │ │ │ │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey) - │ │ │ │ │ ordering: +conrelid - │ │ │ │ │ estimated row count: 1,000 (missing stats) - │ │ │ │ │ table: pg_constraint@pg_constraint_conrelid_idx - │ │ │ │ │ - │ │ │ │ └── • filter - │ │ │ │ │ columns: (oid, nspname) - │ │ │ │ │ estimated row count: 10 (missing stats) - │ │ │ │ │ filter: nspname = 'public' - │ │ │ │ │ - │ │ │ │ └── • virtual table - │ │ │ │ columns: (oid, nspname) - │ │ │ │ estimated row count: 1,000 (missing stats) - │ │ │ │ table: pg_namespace@primary - │ │ │ │ - │ │ │ └── • project set - │ │ │ │ columns: (generate_series) - │ │ │ │ estimated row count: 10 - │ │ │ │ render 0: generate_series(1, 32) - │ │ │ │ - │ │ │ └── • emptyrow - │ │ │ columns: () - │ │ │ - │ │ └── • virtual table - │ │ columns: (oid, relname, relnamespace) - │ │ estimated row count: 1,000 (missing stats) - │ │ table: pg_class@primary + │ ├── • virtual table + │ │ columns: (oid, nspname) + │ │ estimated row count: 1,000 (missing stats) + │ │ table: pg_namespace@primary │ │ │ └── • virtual table - │ columns: (oid, nspname) + │ columns: (oid, relname, relnamespace) │ estimated row count: 1,000 (missing stats) - │ table: pg_namespace@primary + │ table: pg_class@primary │ └── • hash join (inner) - │ columns: (objid, refobjid, oid, relname, relkind) - │ estimated row count: 99 (missing stats) - │ equality: (refobjid) = (oid) + │ columns: (attrelid, attname, attnum, attrelid, attname, attnum, objid, refobjid, oid, relname, relkind, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series) + │ estimated row count: 1,779 (missing stats) + │ equality: (attrelid) = (oid) + │ pred: attnum = conkey[generate_series] │ ├── • virtual table - │ columns: (objid, refobjid) + │ columns: (attrelid, attname, attnum) │ estimated row count: 1,000 (missing stats) - │ table: pg_depend@primary + │ table: pg_attribute@primary │ - └── • filter - │ columns: (oid, relname, relkind) - │ estimated row count: 10 (missing stats) - │ filter: relkind = 'i' + └── • cross join (inner) + │ columns: (attrelid, attname, attnum, objid, refobjid, oid, relname, relkind, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname, generate_series) + │ estimated row count: 539 (missing stats) + │ pred: attnum = confkey[generate_series] │ - └── • virtual table - columns: (oid, relname, relkind) - estimated row count: 1,000 (missing stats) - table: pg_class@primary + ├── • hash join (inner) + │ │ columns: (attrelid, attname, attnum, objid, refobjid, oid, relname, relkind, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname) + │ │ estimated row count: 163 (missing stats) + │ │ equality: (attrelid) = (confrelid) + │ │ + │ ├── • virtual table + │ │ columns: (attrelid, attname, attnum) + │ │ estimated row count: 1,000 (missing stats) + │ │ table: pg_attribute@primary + │ │ + │ └── • hash join (inner) + │ │ columns: (objid, refobjid, oid, relname, relkind, oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname) + │ │ estimated row count: 17 (missing stats) + │ │ equality: (objid) = (oid) + │ │ + │ ├── • hash join (inner) + │ │ │ columns: (objid, refobjid, oid, relname, relkind) + │ │ │ estimated row count: 99 (missing stats) + │ │ │ equality: (refobjid) = (oid) + │ │ │ + │ │ ├── • virtual table + │ │ │ columns: (objid, refobjid) + │ │ │ estimated row count: 1,000 (missing stats) + │ │ │ table: pg_depend@primary + │ │ │ + │ │ └── • filter + │ │ │ columns: (oid, relname, relkind) + │ │ │ estimated row count: 10 (missing stats) + │ │ │ filter: relkind = 'i' + │ │ │ + │ │ └── • virtual table + │ │ columns: (oid, relname, relkind) + │ │ estimated row count: 1,000 (missing stats) + │ │ table: pg_class@primary + │ │ + │ └── • hash join (inner) + │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace, oid, nspname) + │ │ estimated row count: 11 (missing stats) + │ │ equality: (relnamespace) = (oid) + │ │ + │ ├── • virtual table lookup join (inner) + │ │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey, oid, relname, relnamespace) + │ │ │ estimated row count: 10 (missing stats) + │ │ │ table: pg_class@pg_class_oid_idx + │ │ │ equality: (conrelid) = (oid) + │ │ │ pred: relname = 'orders' + │ │ │ + │ │ └── • filter + │ │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey) + │ │ │ estimated row count: 10 (missing stats) + │ │ │ filter: contype = 'f' + │ │ │ + │ │ └── • virtual table + │ │ columns: (oid, conname, contype, condeferrable, condeferred, conrelid, confrelid, confupdtype, confdeltype, conkey, confkey) + │ │ estimated row count: 1,000 (missing stats) + │ │ table: pg_constraint@primary + │ │ + │ └── • filter + │ │ columns: (oid, nspname) + │ │ estimated row count: 10 (missing stats) + │ │ filter: nspname = 'public' + │ │ + │ └── • virtual table + │ columns: (oid, nspname) + │ estimated row count: 1,000 (missing stats) + │ table: pg_namespace@primary + │ + └── • project set + │ columns: (generate_series) + │ estimated row count: 10 + │ render 0: generate_series(1, 32) + │ + └── • emptyrow + columns: () # Ensure that left joins on non-null foreign keys turn into inner joins statement ok diff --git a/pkg/sql/opt/xform/join_order_builder.go b/pkg/sql/opt/xform/join_order_builder.go index 20f838094d28..e721f492fa3f 100644 --- a/pkg/sql/opt/xform/join_order_builder.go +++ b/pkg/sql/opt/xform/join_order_builder.go @@ -1359,24 +1359,6 @@ func commute(op opt.Operator) bool { // ON x = a // func assoc(edgeA, edgeB *edge) bool { - if edgeB.ses.intersects(edgeA.op.leftVertexes) || edgeA.ses.intersects(edgeB.op.rightVertexes) { - // Ensure that application of the associative property would not lead to - // 'orphaned' predicates, where one or more referenced relations are not in - // the resulting join's inputs. Take as an example this reordering that - // results from applying the associative property: - // - // SELECT * FROM (SELECT * FROM xy INNER JOIN ab ON y = a) - // INNER JOIN uv - // ON x = u - // => - // SELECT * FROM xy - // INNER JOIN (SELECT * FROM ab INNER JOIN uv ON x = u) - // ON y = a - // - // Note that the x = u predicate references the xy relation, which is not - // in that join's inputs. Therefore, this transformation is invalid. - return false - } return checkProperty(assocTable, edgeA, edgeB) } @@ -1399,11 +1381,6 @@ func assoc(edgeA, edgeB *edge) bool { // INNER JOIN ab ON x = a // func leftAsscom(edgeA, edgeB *edge) bool { - if edgeB.ses.intersects(edgeA.op.rightVertexes) || edgeA.ses.intersects(edgeB.op.rightVertexes) { - // Ensure that application of the left-asscom property would not lead to - // 'orphaned' predicates. See the assoc() comment for why this is necessary. - return false - } return checkProperty(leftAsscomTable, edgeA, edgeB) } @@ -1428,11 +1405,6 @@ func leftAsscom(edgeA, edgeB *edge) bool { // ON x = a // func rightAsscom(edgeA, edgeB *edge) bool { - if edgeB.ses.intersects(edgeA.op.leftVertexes) || edgeA.ses.intersects(edgeB.op.leftVertexes) { - // Ensure that application of the right-asscom property would not lead to - // 'orphaned' predicates. See the assoc() comment for why this is necessary. - return false - } return checkProperty(rightAsscomTable, edgeA, edgeB) } diff --git a/pkg/sql/opt/xform/join_order_builder_test.go b/pkg/sql/opt/xform/join_order_builder_test.go index f37e325f5870..a0786a59b77b 100644 --- a/pkg/sql/opt/xform/join_order_builder_test.go +++ b/pkg/sql/opt/xform/join_order_builder_test.go @@ -381,6 +381,22 @@ func TestJoinOrderBuilder_CalcTES(t *testing.T) { expectedTES: "ABC", expectedRules: "", }, + { // 20 + // SELECT * FROM ( + // SELECT * FROM ( + // SELECT * FROM A + // INNER JOIN B ON A.u = B.u + // ) INNER JOIN C ON B.v = C.v + // ) INNER JOIN D ON A.w = D.w + rootEdge: testEdge{joinOp: opt.InnerJoinOp, left: "ABC", right: "D", ses: "AD", notNull: "AD"}, + leftChildEdges: []testEdge{ + {joinOp: opt.InnerJoinOp, left: "AB", right: "C", ses: "BC", notNull: "BC"}, + {joinOp: opt.InnerJoinOp, left: "A", right: "B", ses: "AB", notNull: "AB"}, + }, + rightChildEdges: []testEdge{}, + expectedTES: "AD", + expectedRules: "", + }, } for i, tc := range testCases { diff --git a/pkg/sql/opt/xform/testdata/external/tpce b/pkg/sql/opt/xform/testdata/external/tpce index ae2c7a5cb80c..38650c3b3a14 100644 --- a/pkg/sql/opt/xform/testdata/external/tpce +++ b/pkg/sql/opt/xform/testdata/external/tpce @@ -832,7 +832,7 @@ project │ │ │ ├── fd: ()-->(10), (11)-->(12), (18)-->(20), (25)-->(31), (18)==(9,11,25), (25)==(9,11,18), (11)==(9,18,25), (9)==(11,18,25) │ │ │ ├── inner-join (lookup security) │ │ │ │ ├── columns: symb:9!null dm_date:10!null dm_s_symb:11!null dm_close:12!null s_symb:25!null s_num_out:31!null - │ │ │ │ ├── key columns: [11] = [25] + │ │ │ │ ├── key columns: [9] = [25] │ │ │ │ ├── lookup columns are key │ │ │ │ ├── fd: ()-->(10), (11)-->(12), (25)-->(31), (11)==(9,25), (25)==(9,11), (9)==(11,25) │ │ │ │ ├── inner-join (lookup daily_market) @@ -1004,7 +1004,7 @@ project │ │ │ ├── fd: ()-->(36), (37)-->(38), (44)-->(46), (51)-->(57), (44)==(35,37,51), (51)==(35,37,44), (37)==(35,44,51), (35)==(37,44,51) │ │ │ ├── inner-join (lookup security) │ │ │ │ ├── columns: symb:35!null dm_date:36!null dm_s_symb:37!null dm_close:38!null s_symb:51!null s_num_out:57!null - │ │ │ │ ├── key columns: [37] = [51] + │ │ │ │ ├── key columns: [35] = [51] │ │ │ │ ├── lookup columns are key │ │ │ │ ├── key: (51) │ │ │ │ ├── fd: ()-->(36), (37)-->(38), (51)-->(57), (37)==(35,51), (51)==(35,37), (35)==(37,51) @@ -1198,7 +1198,7 @@ project │ │ │ ├── fd: ()-->(7), (8)-->(9), (15)-->(17), (22)-->(28), (15)==(6,8,22), (22)==(6,8,15), (8)==(6,15,22), (6)==(8,15,22) │ │ │ ├── inner-join (lookup security) │ │ │ │ ├── columns: symb:6!null dm_date:7!null dm_s_symb:8!null dm_close:9!null s_symb:22!null s_num_out:28!null - │ │ │ │ ├── key columns: [8] = [22] + │ │ │ │ ├── key columns: [6] = [22] │ │ │ │ ├── lookup columns are key │ │ │ │ ├── key: (22) │ │ │ │ ├── fd: ()-->(7), (8)-->(9), (22)-->(28), (8)==(6,22), (22)==(6,8), (6)==(8,22) diff --git a/pkg/sql/opt/xform/testdata/rules/join_order b/pkg/sql/opt/xform/testdata/rules/join_order index add00b2da1be..a02294127b6f 100644 --- a/pkg/sql/opt/xform/testdata/rules/join_order +++ b/pkg/sql/opt/xform/testdata/rules/join_order @@ -657,7 +657,7 @@ memo (optimized, ~62KB, required=[presentation: b:1,x:2,c:5,y:6,d:9,z:10,a:13,b: │ └── [] │ ├── best: (scan dz,cols=(9,10)) │ └── cost: 1064.42 - ├── G11: (inner-join G2 G14 G4) (inner-join G14 G2 G4) (inner-join G5 G16 G4) (inner-join G16 G5 G4) (inner-join G8 G18 G23) (inner-join G18 G8 G23) (merge-join G14 G2 G19 inner-join,+6,+2) (merge-join G16 G5 G19 inner-join,+2,+6) (lookup-join G8 G19 abc,keyCols=[6],outCols=(1,2,5,6,13-16)) (merge-join G18 G8 G19 inner-join,+13,+6) + ├── G11: (inner-join G2 G14 G4) (inner-join G14 G2 G4) (inner-join G5 G16 G4) (inner-join G16 G5 G4) (inner-join G8 G18 G23) (inner-join G18 G8 G23) (merge-join G14 G2 G19 inner-join,+6,+2) (merge-join G16 G5 G19 inner-join,+2,+6) (lookup-join G8 G19 abc,keyCols=[2],outCols=(1,2,5,6,13-16)) (merge-join G18 G8 G19 inner-join,+13,+2) │ ├── [ordering: +(2|6|13)] │ │ ├── best: (merge-join G14="[ordering: +(6|13)]" G2="[ordering: +2]" G19 inner-join,+6,+2) │ │ └── cost: 3860.48 @@ -672,12 +672,12 @@ memo (optimized, ~62KB, required=[presentation: b:1,x:2,c:5,y:6,d:9,z:10,a:13,b: │ └── [] │ ├── best: (inner-join G2 G10 G21) │ └── cost: 2257.02 - ├── G14: (inner-join G5 G18 G23) (inner-join G18 G5 G23) (lookup-join G5 G19 abc,keyCols=[6],outCols=(5,6,13-16)) (merge-join G18 G5 G19 inner-join,+13,+6) + ├── G14: (inner-join G5 G18 G25) (inner-join G18 G5 G25) (lookup-join G5 G19 abc,keyCols=[6],outCols=(5,6,13-16)) (merge-join G18 G5 G19 inner-join,+13,+6) │ ├── [ordering: +(6|13)] │ │ ├── best: (merge-join G18="[ordering: +13]" G5="[ordering: +6]" G19 inner-join,+13,+6) │ │ └── cost: 2438.64 │ └── [] - │ ├── best: (inner-join G5 G18 G23) + │ ├── best: (inner-join G5 G18 G25) │ └── cost: 2209.31 ├── G15: (inner-join G5 G10 G7) (inner-join G10 G5 G7) │ ├── [ordering: +(6|10)] @@ -686,12 +686,12 @@ memo (optimized, ~62KB, required=[presentation: b:1,x:2,c:5,y:6,d:9,z:10,a:13,b: │ └── [] │ ├── best: (inner-join G5 G10 G7) │ └── cost: 2257.02 - ├── G16: (inner-join G2 G18 G25) (inner-join G18 G2 G25) (lookup-join G2 G19 abc,keyCols=[2],outCols=(1,2,13-16)) (merge-join G18 G2 G19 inner-join,+13,+2) + ├── G16: (inner-join G2 G18 G23) (inner-join G18 G2 G23) (lookup-join G2 G19 abc,keyCols=[2],outCols=(1,2,13-16)) (merge-join G18 G2 G19 inner-join,+13,+2) │ ├── [ordering: +(2|13)] │ │ ├── best: (merge-join G18="[ordering: +13]" G2="[ordering: +2]" G19 inner-join,+13,+2) │ │ └── cost: 2438.64 │ └── [] - │ ├── best: (inner-join G2 G18 G25) + │ ├── best: (inner-join G2 G18 G23) │ └── cost: 2209.31 ├── G17: (inner-join G2 G15 G4) (inner-join G15 G2 G4) (inner-join G5 G13 G7) (inner-join G13 G5 G7) (inner-join G8 G10 G7) (inner-join G10 G8 G7) │ ├── [ordering: +(2|6|10)] @@ -718,9 +718,9 @@ memo (optimized, ~62KB, required=[presentation: b:1,x:2,c:5,y:6,d:9,z:10,a:13,b: ├── G27: (variable y) ├── G28: (eq G26 G29) ├── G29: (variable z) - ├── G30: (eq G27 G31) + ├── G30: (eq G26 G31) ├── G31: (variable a) - └── G32: (eq G26 G31) + └── G32: (eq G27 G31) opt SELECT * FROM bx, cy, dz, abc WHERE x = y AND y = z AND z = a @@ -2458,3 +2458,191 @@ AND EXISTS (SELECT 1 FROM abc WHERE a = y) ---- Rules Applied: 148 Groups Added: 80 + + +# Regression test for #76522. Do not produce query plans where some of the +# original filters have been omitted. + +exec-ddl +CREATE TABLE t76522_1 ( + a INT NOT NULL, + b INT NOT NULL, + PRIMARY KEY (a ASC, b ASC) +) +---- + +exec-ddl +CREATE TABLE t76522_2 ( + a INT NOT NULL, + c INT, + should_not_be_eliminated INT, + PRIMARY KEY (a ASC) +) +---- + +exec-ddl +CREATE TABLE t76522_3 ( + a INT NOT NULL, + d INT NOT NULL, + f INT, + g INT, + PRIMARY KEY (a ASC, d ASC) +) +---- + +exec-ddl +CREATE TABLE t76522_4 ( + e INT NOT NULL, + f INT, + g INT, + PRIMARY KEY (e ASC) +) +---- + +exec-ddl +CREATE TABLE t76522_5 ( + h INT NOT NULL, + f INT NOT NULL, + g INT NOT NULL, + b INT, + should_not_be_eliminated INT, + c INT, + PRIMARY KEY (h ASC, f ASC, g ASC) +) +---- + +# Give t76522_1 many rows where a has many distincts. +exec-ddl +ALTER TABLE t76522_1 INJECT STATISTICS '[ + { + "columns": [ + "a" + ], + "created_at": "2022-01-17 12:51:38.433911", + "distinct_count": 9161427, + "null_count": 0, + "row_count": 44484238 + } +]' +---- + +# Give t76522_2 many rows where a has many distincts. +exec-ddl +ALTER TABLE t76522_2 INJECT STATISTICS '[ + { + "columns": [ + "a" + ], + "created_at": "2022-01-17 12:51:38.433911", + "distinct_count": 17014025, + "null_count": 0, + "row_count": 17024553 + } +]' +---- + +# Give t76522_3 many rows where a has many distincts. +exec-ddl +ALTER TABLE t76522_3 INJECT STATISTICS '[ + { + "columns": [ + "a" + ], + "created_at": "2022-01-17 12:51:38.433911", + "distinct_count": 17187349, + "null_count": 0, + "row_count": 18138540 + } +]' +---- + +# Give t76522_4 many rows where e has many distincts. +exec-ddl +ALTER TABLE t76522_4 INJECT STATISTICS '[ + { + "columns": [ + "e" + ], + "created_at": "2022-01-17 12:51:38.433911", + "distinct_count": 346919, + "null_count": 0, + "row_count": 346109 + } +]'; +---- + +# Give t5 few rows. +exec-ddl +ALTER TABLE t76522_5 INJECT STATISTICS '[ + { + "columns": [ + "h" + ], + "created_at": "2022-01-17 12:51:38.433911", + "distinct_count": 119, + "null_count": 0, + "row_count": 119 + } +]' +---- + +# Prior to the fix, these filters were missing from the query plan: +# +# t5.c = t2.c +# t2.should_not_be_eliminated = t5.should_not_be_eliminated +# +opt +SELECT + t2.a +FROM + t76522_1 AS t1 + INNER JOIN t76522_2 AS t2 ON t1.a = t2.a + INNER JOIN t76522_3 AS t3 ON t1.a = t3.a + INNER JOIN t76522_4 AS t4 ON t3.d = t4.e + INNER JOIN t76522_5 AS t5 ON + t4.f = t5.f + AND t4.g = t5.g + AND t5.b = t1.b + AND t5.c = t2.c +WHERE + t1.a = 123456 AND t2.should_not_be_eliminated = t5.should_not_be_eliminated; +---- +project + ├── columns: a:5!null + ├── fd: ()-->(5) + └── inner-join (lookup t76522_1 [as=t1]) + ├── columns: t1.a:1!null t1.b:2!null t2.a:5!null t2.c:6!null t2.should_not_be_eliminated:7!null t3.a:10!null d:11!null e:16!null t4.f:17!null t4.g:18!null t5.f:22!null t5.g:23!null t5.b:24!null t5.should_not_be_eliminated:25!null t5.c:26!null + ├── key columns: [5 24] = [1 2] + ├── lookup columns are key + ├── fd: ()-->(1,5-7,10,25,26), (1)==(5,10), (5)==(1,10), (10)==(1,5), (16)-->(17,18), (11)==(16), (16)==(11), (17)==(22), (22)==(17), (18)==(23), (23)==(18), (2)==(24), (24)==(2), (6)==(26), (26)==(6), (7)==(25), (25)==(7) + ├── inner-join (lookup t76522_2 [as=t2]) + │ ├── columns: t2.a:5!null t2.c:6!null t2.should_not_be_eliminated:7!null t3.a:10!null d:11!null e:16!null t4.f:17!null t4.g:18!null t5.f:22!null t5.g:23!null t5.b:24 t5.should_not_be_eliminated:25!null t5.c:26!null + │ ├── key columns: [10] = [5] + │ ├── lookup columns are key + │ ├── fd: ()-->(5-7,10,25,26), (16)-->(17,18), (17)==(22), (22)==(17), (18)==(23), (23)==(18), (11)==(16), (16)==(11), (6)==(26), (26)==(6), (7)==(25), (25)==(7), (5)==(10), (10)==(5) + │ ├── inner-join (hash) + │ │ ├── columns: t3.a:10!null d:11!null e:16!null t4.f:17!null t4.g:18!null t5.f:22!null t5.g:23!null t5.b:24 t5.should_not_be_eliminated:25 t5.c:26 + │ │ ├── fd: ()-->(10), (16)-->(17,18), (17)==(22), (22)==(17), (18)==(23), (23)==(18), (11)==(16), (16)==(11) + │ │ ├── scan t76522_5 [as=t5] + │ │ │ └── columns: t5.f:22!null t5.g:23!null t5.b:24 t5.should_not_be_eliminated:25 t5.c:26 + │ │ ├── inner-join (lookup t76522_4 [as=t4]) + │ │ │ ├── columns: t3.a:10!null d:11!null e:16!null t4.f:17 t4.g:18 + │ │ │ ├── key columns: [11] = [16] + │ │ │ ├── lookup columns are key + │ │ │ ├── key: (16) + │ │ │ ├── fd: ()-->(10), (16)-->(17,18), (11)==(16), (16)==(11) + │ │ │ ├── scan t76522_3 [as=t3] + │ │ │ │ ├── columns: t3.a:10!null d:11!null + │ │ │ │ ├── constraint: /10/11: [/123456 - /123456] + │ │ │ │ ├── key: (11) + │ │ │ │ └── fd: ()-->(10) + │ │ │ └── filters (true) + │ │ └── filters + │ │ ├── t4.f:17 = t5.f:22 [outer=(17,22), constraints=(/17: (/NULL - ]; /22: (/NULL - ]), fd=(17)==(22), (22)==(17)] + │ │ └── t4.g:18 = t5.g:23 [outer=(18,23), constraints=(/18: (/NULL - ]; /23: (/NULL - ]), fd=(18)==(23), (23)==(18)] + │ └── filters + │ ├── t5.c:26 = t2.c:6 [outer=(6,26), constraints=(/6: (/NULL - ]; /26: (/NULL - ]), fd=(6)==(26), (26)==(6)] + │ ├── t2.should_not_be_eliminated:7 = t5.should_not_be_eliminated:25 [outer=(7,25), constraints=(/7: (/NULL - ]; /25: (/NULL - ]), fd=(7)==(25), (25)==(7)] + │ └── t2.a:5 = 123456 [outer=(5), constraints=(/5: [/123456 - /123456]; tight), fd=()-->(5)] + └── filters + └── t1.a:1 = 123456 [outer=(1), constraints=(/1: [/123456 - /123456]; tight), fd=()-->(1)]