Skip to content

Commit 470d554

Browse files
authored
planner: clean the one side filters for outer join reorder which is not done in #44409 (#45565) (#45586)
ref #44409, close #45564
1 parent 369d7bc commit 470d554

File tree

5 files changed

+108
-16
lines changed

5 files changed

+108
-16
lines changed

planner/core/main_test.go

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -34,6 +34,8 @@ func TestMain(m *testing.M) {
3434
flag.Parse()
3535
testDataMap.LoadTestSuiteData("testdata", "plan_suite_unexported")
3636
testDataMap.LoadTestSuiteData("testdata", "index_merge_suite")
37+
testDataMap.LoadTestSuiteData("testdata", "join_reorder_suite")
38+
3739
indexMergeSuiteData = testDataMap["index_merge_suite"]
3840
planSuiteUnexportedData = testDataMap["plan_suite_unexported"]
3941
opts := []goleak.Option{
@@ -56,3 +58,7 @@ func TestMain(m *testing.M) {
5658
func GetIndexMergeSuiteData() testdata.TestData {
5759
return testDataMap["index_merge_suite"]
5860
}
61+
62+
func GetJoinReorderData() testdata.TestData {
63+
return testDataMap["join_reorder_suite"]
64+
}

planner/core/rule_join_reorder.go

Lines changed: 6 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -533,12 +533,17 @@ func (s *baseSingleGroupJoinOrderSolver) makeJoin(leftPlan, rightPlan LogicalPla
533533
remainOtherConds, otherConds = expression.FilterOutInPlace(remainOtherConds, func(expr expression.Expression) bool {
534534
return expression.ExprFromSchema(expr, mergedSchema)
535535
})
536-
if (joinType.JoinType == LeftOuterJoin || joinType.JoinType == RightOuterJoin || joinType.JoinType == LeftOuterSemiJoin || joinType.JoinType == AntiLeftOuterSemiJoin) && len(otherConds) > 0 {
536+
537+
if joinType.JoinType == LeftOuterJoin || joinType.JoinType == RightOuterJoin || joinType.JoinType == LeftOuterSemiJoin || joinType.JoinType == AntiLeftOuterSemiJoin {
537538
// the original outer join's other conditions has been bound to the outer join Edge,
538539
// these remained other condition here shouldn't be appended to it because on-mismatch
539540
// logic will produce more append-null rows which is banned in original semantic.
540541
remainOtherConds = append(remainOtherConds, otherConds...) // nozero
542+
remainOtherConds = append(remainOtherConds, leftConds...) // nozero
543+
remainOtherConds = append(remainOtherConds, rightConds...) // nozero
541544
otherConds = otherConds[:0]
545+
leftConds = leftConds[:0]
546+
rightConds = rightConds[:0]
542547
}
543548
if len(joinType.outerBindCondition) > 0 {
544549
remainOBOtherConds := make([]expression.Expression, len(joinType.outerBindCondition))

planner/core/rule_join_reorder_test.go

Lines changed: 24 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,9 @@ package core_test
1717
import (
1818
"testing"
1919

20+
"github.com/pingcap/tidb/planner/core"
2021
"github.com/pingcap/tidb/testkit"
22+
"github.com/pingcap/tidb/testkit/testdata"
2123
"github.com/stretchr/testify/require"
2224
)
2325

@@ -82,21 +84,28 @@ func TestAdditionOtherConditionsRemained4OuterJoin(t *testing.T) {
8284
tk.MustExec("INSERT INTO queries_program(`id`, `identifier_id`) values(8, 13), (9, 14);")
8385
tk.MustExec("INSERT INTO queries_channel(`id`, `identifier_id`) values(5, 13);")
8486

85-
tk.MustQuery("SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC;").Check(testkit.Rows("" +
86-
"13 i1"))
87-
tk.MustQuery("SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` RIGHT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC;").Check(testkit.Rows("" +
88-
"13 i1"))
89-
tk.MustQuery("explain format = 'brief' SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC;").Check(testkit.Rows(""+
90-
"Sort 2.50 root test.queries_identifier.id",
91-
"└─Projection 2.50 root test.queries_identifier.id, test.queries_identifier.name",
92-
" └─Selection 2.50 root or(and(eq(test.queries_channel.id, 5), eq(test.queries_program.id, 9)), eq(test.queries_program.id, 8))",
93-
" └─IndexJoin 3.12 root left outer join, inner:IndexReader, outer key:test.queries_identifier.id, inner key:test.queries_channel.identifier_id, equal cond:eq(test.queries_identifier.id, test.queries_channel.identifier_id)",
94-
" ├─IndexHashJoin(Build) 2.50 root inner join, inner:TableReader, outer key:test.queries_program.identifier_id, inner key:test.queries_identifier.id, equal cond:eq(test.queries_program.identifier_id, test.queries_identifier.id)",
95-
" │ ├─Batch_Point_Get(Build) 2.00 root table:queries_program handle:[8 9], keep order:false, desc:false",
96-
" │ └─TableReader(Probe) 2.00 root data:TableRangeScan",
97-
" │ └─TableRangeScan 2.00 cop[tikv] table:queries_identifier range: decided by [test.queries_program.identifier_id], keep order:false, stats:pseudo",
98-
" └─IndexReader(Probe) 2.50 root index:IndexRangeScan",
99-
" └─IndexRangeScan 2.50 cop[tikv] table:queries_channel, index:identifier_id(identifier_id) range: decided by [eq(test.queries_channel.identifier_id, test.queries_identifier.id)], keep order:false, stats:pseudo"))
87+
tk.MustExec("create table t(a int)")
88+
tk.MustExec("create table t1(a int, b int)")
89+
tk.MustExec("create table t2(a int, b int, c int)")
90+
tk.MustExec("create table t3(a int, b int)")
91+
tk.MustExec("create table t4(a int, b int)")
92+
93+
testData := core.GetJoinReorderData()
94+
var (
95+
input []string
96+
output []struct {
97+
SQL string
98+
Output []string
99+
}
100+
)
101+
testData.LoadTestCases(t, &input, &output)
102+
for i, sql := range input {
103+
testdata.OnRecord(func() {
104+
output[i].SQL = sql
105+
output[i].Output = testdata.ConvertRowsToStrings(tk.MustQuery(sql).Rows())
106+
})
107+
tk.MustQuery(sql).Check(testkit.Rows(output[i].Output...))
108+
}
100109
}
101110

102111
func TestOuterJoinWIthEqCondCrossInnerJoin(t *testing.T) {
Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
[
2+
{
3+
"name": "TestAdditionOtherConditionsRemained4OuterJoin",
4+
"cases": [
5+
"SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC",
6+
"SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` RIGHT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC",
7+
"explain format = 'brief' SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC;",
8+
// The where clause should be a Selection out of joins.
9+
"explain format='brief' select * from t left join t1 on t.a=t1.a inner join t2 on t.a=t2.a and t2.c = 100 left join t3 on t2.a=t3.a and t3.b > 1 left join t4 on t2.a = t4.a where (t2.b > 100 or t.a > 10 or t1.b < 10)"
10+
]
11+
}
12+
]
Lines changed: 60 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,60 @@
1+
[
2+
{
3+
"Name": "TestAdditionOtherConditionsRemained4OuterJoin",
4+
"Cases": [
5+
{
6+
"SQL": "SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC",
7+
"Output": [
8+
"13 i1"
9+
]
10+
},
11+
{
12+
"SQL": "SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` RIGHT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC",
13+
"Output": [
14+
"13 i1"
15+
]
16+
},
17+
{
18+
"SQL": "explain format = 'brief' SELECT `queries_identifier`.`id`, `queries_identifier`.`name` FROM `queries_identifier` LEFT OUTER JOIN `queries_channel` ON (`queries_identifier`.`id` = `queries_channel`.`identifier_id`) INNER JOIN `queries_program` ON (`queries_identifier`.`id` = `queries_program`.`identifier_id`) WHERE ((`queries_channel`.`id` = 5 AND `queries_program`.`id` = 9) OR `queries_program`.`id` = 8) ORDER BY `queries_identifier`.`id` ASC;",
19+
"Output": [
20+
"Sort 2.50 root test.queries_identifier.id",
21+
"└─Projection 2.50 root test.queries_identifier.id, test.queries_identifier.name",
22+
" └─Selection 2.50 root or(and(eq(test.queries_channel.id, 5), eq(test.queries_program.id, 9)), eq(test.queries_program.id, 8))",
23+
" └─IndexJoin 3.12 root left outer join, inner:IndexReader, outer key:test.queries_identifier.id, inner key:test.queries_channel.identifier_id, equal cond:eq(test.queries_identifier.id, test.queries_channel.identifier_id)",
24+
" ├─IndexHashJoin(Build) 2.50 root inner join, inner:TableReader, outer key:test.queries_program.identifier_id, inner key:test.queries_identifier.id, equal cond:eq(test.queries_program.identifier_id, test.queries_identifier.id)",
25+
" │ ├─Batch_Point_Get(Build) 2.00 root table:queries_program handle:[8 9], keep order:false, desc:false",
26+
" │ └─TableReader(Probe) 2.00 root data:TableRangeScan",
27+
" │ └─TableRangeScan 2.00 cop[tikv] table:queries_identifier range: decided by [test.queries_program.identifier_id], keep order:false, stats:pseudo",
28+
" └─IndexReader(Probe) 2.50 root index:IndexRangeScan",
29+
" └─IndexRangeScan 2.50 cop[tikv] table:queries_channel, index:identifier_id(identifier_id) range: decided by [eq(test.queries_channel.identifier_id, test.queries_identifier.id)], keep order:false, stats:pseudo"
30+
]
31+
},
32+
{
33+
"SQL": "explain format='brief' select * from t left join t1 on t.a=t1.a inner join t2 on t.a=t2.a and t2.c = 100 left join t3 on t2.a=t3.a and t3.b > 1 left join t4 on t2.a = t4.a where (t2.b > 100 or t.a > 10 or t1.b < 10)",
34+
"Output": [
35+
"Projection 19.51 root test.t.a, test.t1.a, test.t1.b, test.t2.a, test.t2.b, test.t2.c, test.t3.a, test.t3.b, test.t4.a, test.t4.b",
36+
"└─Selection 19.51 root or(gt(test.t2.b, 100), or(gt(test.t.a, 10), lt(test.t1.b, 10))), or(gt(test.t2.b, 100), or(gt(test.t2.a, 10), lt(test.t1.b, 10)))",
37+
" └─HashJoin 24.39 root left outer join, equal:[eq(test.t2.a, test.t4.a)]",
38+
" ├─HashJoin(Build) 19.51 root left outer join, equal:[eq(test.t.a, test.t1.a)]",
39+
" │ ├─HashJoin(Build) 15.61 root inner join, equal:[eq(test.t2.a, test.t.a)]",
40+
" │ │ ├─HashJoin(Build) 12.49 root left outer join, equal:[eq(test.t2.a, test.t3.a)]",
41+
" │ │ │ ├─TableReader(Build) 9.99 root data:Selection",
42+
" │ │ │ │ └─Selection 9.99 cop[tikv] eq(test.t2.c, 100), not(isnull(test.t2.a))",
43+
" │ │ │ │ └─TableFullScan 10000.00 cop[tikv] table:t2 keep order:false, stats:pseudo",
44+
" │ │ │ └─TableReader(Probe) 3330.00 root data:Selection",
45+
" │ │ │ └─Selection 3330.00 cop[tikv] gt(test.t3.b, 1), not(isnull(test.t3.a))",
46+
" │ │ │ └─TableFullScan 10000.00 cop[tikv] table:t3 keep order:false, stats:pseudo",
47+
" │ │ └─TableReader(Probe) 9990.00 root data:Selection",
48+
" │ │ └─Selection 9990.00 cop[tikv] not(isnull(test.t.a))",
49+
" │ │ └─TableFullScan 10000.00 cop[tikv] table:t keep order:false, stats:pseudo",
50+
" │ └─TableReader(Probe) 9990.00 root data:Selection",
51+
" │ └─Selection 9990.00 cop[tikv] not(isnull(test.t1.a))",
52+
" │ └─TableFullScan 10000.00 cop[tikv] table:t1 keep order:false, stats:pseudo",
53+
" └─TableReader(Probe) 9990.00 root data:Selection",
54+
" └─Selection 9990.00 cop[tikv] not(isnull(test.t4.a))",
55+
" └─TableFullScan 10000.00 cop[tikv] table:t4 keep order:false, stats:pseudo"
56+
]
57+
}
58+
]
59+
}
60+
]

0 commit comments

Comments
 (0)