[Commits] 533cf86: MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause

Sergei Petrunia psergey at askmonty.org
Fri May 6 12:30:01 EEST 2016


revision-id: 533cf860ade984abf20f411bcfc96840a20c431b
parent(s): a02d4023db42755b5cb7d0ccb0543fbe94d1b628
committer: Sergei Petrunia
branch nick: 10.1-dbg5
timestamp: 2016-05-06 12:30:01 +0300
message:

MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause

When simplify_joins() converts an outer join to an inner, it should
reset the value of TABLE::dep_tables.  This is needed, because the
function may have already set TABLE::dep_tables according to the outer
join dependency.

---
 mysql-test/r/join_outer.result |   63 ++++++++++++++++++++++++++++++++++++++++
 mysql-test/t/join_outer.test   |   58 ++++++++++++++++++++++++++++++++++++
 sql/sql_select.cc              |    2 ++
 3 files changed, 123 insertions(+)

diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result
index 820d66b..266c833 100644
--- a/mysql-test/r/join_outer.result
+++ b/mysql-test/r/join_outer.result
@@ -2273,4 +2273,67 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	9	
 1	SIMPLE	t2	ref	c	c	5	const	393	Using where
 drop table t1,t2;
+#
+# MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause
+#
+CREATE TABLE t1(i1 int primary key, v1 int, key(v1));
+INSERT INTO t1 VALUES (1, 1);
+INSERT INTO t1 VALUES (2, 2);
+INSERT INTO t1 VALUES (3, 3);
+INSERT INTO t1 VALUES (4, 4);
+INSERT INTO t1 VALUES (5, 3);
+INSERT INTO t1 VALUES (6, 6);
+INSERT INTO t1 VALUES (7, 7);
+INSERT INTO t1 VALUES (8, 8);
+INSERT INTO t1 VALUES (9, 9);
+CREATE TABLE t2(i2 int primary key, v2 int, key(v2));
+INSERT INTO t2 VALUES (1, 1);
+INSERT INTO t2 VALUES (2, 2);
+INSERT INTO t2 VALUES (3, 3);
+INSERT INTO t2 VALUES (4, 4);
+INSERT INTO t2 VALUES (5, 3);
+INSERT INTO t2 VALUES (6, 6);
+INSERT INTO t2 VALUES (7, 7);
+INSERT INTO t2 VALUES (8, 8);
+INSERT INTO t2 VALUES (9, 9);
+CREATE TABLE t3(i3 int primary key, v3 int, key(v3));
+INSERT INTO t3 VALUES (2, 2);
+INSERT INTO t3 VALUES (4, 4);
+INSERT INTO t3 VALUES (6, 6);
+INSERT INTO t3 VALUES (8, 8);
+# This should have a join order of t3,t1,t2 (or t3,t2,t1, the idea is that t3 is the first one)
+EXPLAIN EXTENDED 
+SELECT * FROM 
+(SELECT t1.i1 as i1, t1.v1 as v1,
+t2.i2 as i2, t2.v2 as v2,
+t3.i3 as i3, t3.v3 as v3
+FROM t1 JOIN t2 on t1.i1 = t2.i2
+LEFT JOIN t3 on t2.i2 = t3.i3
+) as w1 
+WHERE v3 = 4;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	filtered	Extra
+1	SIMPLE	t3	ref	PRIMARY,v3	v3	5	const	1	100.00	
+1	SIMPLE	t1	eq_ref	PRIMARY	PRIMARY	4	test.t3.i3	1	100.00	
+1	SIMPLE	t2	eq_ref	PRIMARY	PRIMARY	4	test.t3.i3	1	100.00	
+Warnings:
+Note	1003	select `test`.`t1`.`i1` AS `i1`,`test`.`t1`.`v1` AS `v1`,`test`.`t2`.`i2` AS `i2`,`test`.`t2`.`v2` AS `v2`,`test`.`t3`.`i3` AS `i3`,`test`.`t3`.`v3` AS `v3` from `test`.`t1` join `test`.`t2` join `test`.`t3` where ((`test`.`t3`.`v3` = 4) and (`test`.`t1`.`i1` = `test`.`t3`.`i3`) and (`test`.`t2`.`i2` = `test`.`t3`.`i3`))
+# This should have the same join order like the query above:
+EXPLAIN EXTENDED 
+SELECT * FROM 
+(SELECT t1.i1 as i1, t1.v1 as v1,
+t2.i2 as i2, t2.v2 as v2,
+t3.i3 as i3, t3.v3 as v3
+FROM t1 JOIN t2 on t1.i1 = t2.i2
+LEFT JOIN t3 on t2.i2 = t3.i3
+WHERE t1.i1 = t2.i2
+AND 1 = 1
+) as w2 
+WHERE v3 = 4;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	filtered	Extra
+1	SIMPLE	t3	ref	PRIMARY,v3	v3	5	const	1	100.00	
+1	SIMPLE	t1	eq_ref	PRIMARY	PRIMARY	4	test.t3.i3	1	100.00	
+1	SIMPLE	t2	eq_ref	PRIMARY	PRIMARY	4	test.t3.i3	1	100.00	
+Warnings:
+Note	1003	select `test`.`t1`.`i1` AS `i1`,`test`.`t1`.`v1` AS `v1`,`test`.`t2`.`i2` AS `i2`,`test`.`t2`.`v2` AS `v2`,`test`.`t3`.`i3` AS `i3`,`test`.`t3`.`v3` AS `v3` from `test`.`t1` join `test`.`t2` join `test`.`t3` where ((`test`.`t3`.`v3` = 4) and (`test`.`t1`.`i1` = `test`.`t3`.`i3`) and (`test`.`t2`.`i2` = `test`.`t3`.`i3`))
+drop table t1,t2,t3;
 SET optimizer_switch=@save_optimizer_switch;
diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test
index 9ae6578..a3a1278 100644
--- a/mysql-test/t/join_outer.test
+++ b/mysql-test/t/join_outer.test
@@ -1824,4 +1824,62 @@ explain select * from t1 left join t2 on t2.c is null;
 
 drop table t1,t2;
 
+--echo #
+--echo # MDEV-10006: optimizer doesn't convert outer join to inner on views with WHERE clause
+--echo #
+
+CREATE TABLE t1(i1 int primary key, v1 int, key(v1));
+INSERT INTO t1 VALUES (1, 1);
+INSERT INTO t1 VALUES (2, 2);
+INSERT INTO t1 VALUES (3, 3);
+INSERT INTO t1 VALUES (4, 4);
+INSERT INTO t1 VALUES (5, 3);
+INSERT INTO t1 VALUES (6, 6);
+INSERT INTO t1 VALUES (7, 7);
+INSERT INTO t1 VALUES (8, 8);
+INSERT INTO t1 VALUES (9, 9);
+ 
+CREATE TABLE t2(i2 int primary key, v2 int, key(v2));
+INSERT INTO t2 VALUES (1, 1);
+INSERT INTO t2 VALUES (2, 2);
+INSERT INTO t2 VALUES (3, 3);
+INSERT INTO t2 VALUES (4, 4);
+INSERT INTO t2 VALUES (5, 3);
+INSERT INTO t2 VALUES (6, 6);
+INSERT INTO t2 VALUES (7, 7);
+INSERT INTO t2 VALUES (8, 8);
+INSERT INTO t2 VALUES (9, 9);
+ 
+CREATE TABLE t3(i3 int primary key, v3 int, key(v3));
+INSERT INTO t3 VALUES (2, 2);
+INSERT INTO t3 VALUES (4, 4);
+INSERT INTO t3 VALUES (6, 6);
+INSERT INTO t3 VALUES (8, 8);
+
+--echo # This should have a join order of t3,t1,t2 (or t3,t2,t1, the idea is that t3 is the first one)
+EXPLAIN EXTENDED 
+SELECT * FROM 
+ (SELECT t1.i1 as i1, t1.v1 as v1,
+                 t2.i2 as i2, t2.v2 as v2,
+                 t3.i3 as i3, t3.v3 as v3
+            FROM t1 JOIN t2 on t1.i1 = t2.i2
+       LEFT JOIN t3 on t2.i2 = t3.i3
+ ) as w1 
+WHERE v3 = 4;
+
+--echo # This should have the same join order like the query above:
+EXPLAIN EXTENDED 
+SELECT * FROM 
+ (SELECT t1.i1 as i1, t1.v1 as v1,
+                 t2.i2 as i2, t2.v2 as v2,
+                 t3.i3 as i3, t3.v3 as v3
+            FROM t1 JOIN t2 on t1.i1 = t2.i2
+       LEFT JOIN t3 on t2.i2 = t3.i3
+           WHERE t1.i1 = t2.i2
+             AND 1 = 1
+ ) as w2 
+WHERE v3 = 4;
+
+drop table t1,t2,t3;
+
 SET optimizer_switch=@save_optimizer_switch;
diff --git a/sql/sql_select.cc b/sql/sql_select.cc
index e83f63d..25e71cd 100644
--- a/sql/sql_select.cc
+++ b/sql/sql_select.cc
@@ -14418,6 +14418,8 @@ static void update_const_equal_items(THD *thd, COND *cond, JOIN_TAB *tab,
       if (table->outer_join && !table->embedding && table->table)
         table->table->maybe_null= FALSE;
       table->outer_join= 0;
+      if (!(straight_join || table->straight))
+        table->dep_tables= table->embedding? table->embedding->dep_tables: 0;
       if (table->on_expr)
       {
         /* Add ON expression to the WHERE or upper-level ON condition. */


More information about the commits mailing list