diff options
author | Igor Babaev <igor@askmonty.org> | 2017-02-26 15:40:18 -0800 |
---|---|---|
committer | Igor Babaev <igor@askmonty.org> | 2017-02-27 09:02:41 -0800 |
commit | 5a0fff50f87e20c4e95a84143a0a3bb67e03e29e (patch) | |
tree | 9b5ffd8ae32bc28a3a8a9c7866c2fc23fd11216f | |
parent | 199f88cb9cfb08cefced1b51a7d98fe4c91b7a2e (diff) | |
download | mariadb-git-5a0fff50f87e20c4e95a84143a0a3bb67e03e29e.tar.gz |
Fixed bug mdev-12099.
The function mysql_derived_merge() erroneously did not mark newly formed
AND formulas in ON conditions with the flag abort_on_null. As a result
not_null_tables() calculated incorrectly for these conditions. This
could prevent conversion of embedded outer joins into inner joins.
Changed a test case from table_elim.test to preserve the former execution
plan.
-rw-r--r-- | mysql-test/r/table_elim.result | 5 | ||||
-rw-r--r-- | mysql-test/r/view.result | 83 | ||||
-rw-r--r-- | mysql-test/t/table_elim.test | 4 | ||||
-rw-r--r-- | mysql-test/t/view.test | 60 | ||||
-rw-r--r-- | sql/sql_derived.cc | 3 |
5 files changed, 151 insertions, 4 deletions
diff --git a/mysql-test/r/table_elim.result b/mysql-test/r/table_elim.result index f475198ac02..4505adab443 100644 --- a/mysql-test/r/table_elim.result +++ b/mysql-test/r/table_elim.result @@ -597,7 +597,8 @@ CREATE TABLE t1 (a int(11), b varchar(1)) ; INSERT IGNORE INTO t1 VALUES (0,'g'); CREATE TABLE t3 ( a varchar(1)) ; INSERT IGNORE INTO t3 VALUES ('g'); -CREATE TABLE t2 ( a int(11) NOT NULL, PRIMARY KEY (a)) ; +CREATE TABLE t2 ( a int(11) NOT NULL, PRIMARY KEY (a)); +INSERT INTO t2 VALUES (9), (10); create view v1 as SELECT t1.* FROM t1 LEFT JOIN t2 ON ( t1.a = t2.a ) WHERE t2.a <> 0; SELECT alias1.* FROM t3 LEFT JOIN v1 as alias1 ON ( t3.a = alias1.b ); a b @@ -606,7 +607,7 @@ EXPLAIN SELECT alias1.* FROM t3 LEFT JOIN v1 as alias1 ON ( t3.a = alias1.b ); id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t3 system NULL NULL NULL NULL 1 1 SIMPLE t1 ALL NULL NULL NULL NULL 1 Using where -1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t1.a 1 Using where; Using index +1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t1.a 1 Using index drop view v1; DROP TABLE t1,t2,t3; # diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 6848ba30245..414de5662f3 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -5535,6 +5535,89 @@ Warnings: Warning 1356 View 'test.v1' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them drop view v1; drop table t1,t2; +# +# MDEV-12099: usage of mergeable view with LEFT JOIN +# that can be converted to INNER JOIN +# +create table t1 (a int, b int, key(a)) engine=myisam; +insert into t1 values +(3,20), (7,10), (2,10), (4,30), (8,70), +(7,70), (9,100), (9,60), (8,80), (7,60); +create table t2 (c int, d int, key (c)) engine=myisam; +insert into t2 values +(50,100), (20, 200), (10,300), +(150,100), (120, 200), (110,300), +(250,100), (220, 200), (210,300); +create table t3(e int, f int not null, key(e), unique (f)) engine=myisam; +insert into t3 values +(100, 3), (300, 5), (400, 4), (300,7), +(300,2), (600, 13), (800, 15), (700, 14), +(600, 23), (800, 25), (700, 24); +create view v1 as +select * from t2 left join t3 on t3.e=t2.d where t3.f is not null; +select * +from t1 left join v1 on v1.c=t1.b +where t1.a < 5; +a b c d e f +2 10 10 300 300 5 +2 10 10 300 300 7 +2 10 10 300 300 2 +3 20 NULL NULL NULL NULL +4 30 NULL NULL NULL NULL +select * +from t1 left join ( t2 left join t3 on t3.e=t2.d ) +on t2.c=t1.b and t3.f is not null +where t1.a < 5; +a b c d e f +2 10 10 300 300 5 +2 10 10 300 300 7 +2 10 10 300 300 2 +3 20 NULL NULL NULL NULL +4 30 NULL NULL NULL NULL +explain extended +select * +from t1 left join v1 on v1.c=t1.b +where t1.a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 3 100.00 Using index condition +1 SIMPLE t2 ref c c 5 test.t1.b 2 100.00 Using where +1 SIMPLE t3 ref f,e e 5 test.t2.d 2 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d`,`test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t1` left join (`test`.`t2` join `test`.`t3`) on(((`test`.`t2`.`c` = `test`.`t1`.`b`) and (`test`.`t3`.`e` = `test`.`t2`.`d`) and (`test`.`t3`.`f` is not null) and (`test`.`t1`.`b` is not null) and (`test`.`t2`.`d` is not null))) where (`test`.`t1`.`a` < 5) +explain extended +select * +from t1 left join ( t2 left join t3 on t3.e=t2.d ) +on t2.c=t1.b and t3.f is not null +where t1.a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 3 100.00 Using index condition +1 SIMPLE t2 ref c c 5 test.t1.b 2 100.00 Using where +1 SIMPLE t3 ref f,e e 5 test.t2.d 2 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d`,`test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t1` left join (`test`.`t2` join `test`.`t3`) on(((`test`.`t2`.`c` = `test`.`t1`.`b`) and (`test`.`t3`.`e` = `test`.`t2`.`d`) and (`test`.`t3`.`f` is not null) and (`test`.`t1`.`b` is not null) and (`test`.`t2`.`d` is not null))) where (`test`.`t1`.`a` < 5) +explain extended +select * +from t1 left join v1 on v1.c=t1.b and v1.f=t1.a +where t1.a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 3 100.00 Using index condition +1 SIMPLE t3 eq_ref f,e f 4 test.t1.a 1 100.00 Using where +1 SIMPLE t2 ref c c 5 test.t1.b 2 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d`,`test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t1` left join (`test`.`t2` join `test`.`t3`) on(((`test`.`t2`.`c` = `test`.`t1`.`b`) and (`test`.`t3`.`f` = `test`.`t1`.`a`) and (`test`.`t2`.`d` = `test`.`t3`.`e`) and (`test`.`t1`.`a` is not null) and (`test`.`t1`.`a` is not null) and (`test`.`t1`.`b` is not null))) where (`test`.`t1`.`a` < 5) +explain extended +select * +from t1 left join ( t2 left join t3 on t3.e=t2.d ) +on t2.c=t1.b and t3.f=t1.a and t3.f is not null +where t1.a < 5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 3 100.00 Using index condition +1 SIMPLE t3 eq_ref f,e f 4 test.t1.a 1 100.00 Using where +1 SIMPLE t2 ref c c 5 test.t1.b 2 100.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`c` AS `c`,`test`.`t2`.`d` AS `d`,`test`.`t3`.`e` AS `e`,`test`.`t3`.`f` AS `f` from `test`.`t1` left join (`test`.`t2` join `test`.`t3`) on(((`test`.`t2`.`c` = `test`.`t1`.`b`) and (`test`.`t3`.`f` = `test`.`t1`.`a`) and (`test`.`t2`.`d` = `test`.`t3`.`e`) and (`test`.`t1`.`a` is not null) and (`test`.`t1`.`a` is not null) and (`test`.`t1`.`b` is not null))) where (`test`.`t1`.`a` < 5) +drop view v1; +drop table t1,t2,t3; # ----------------------------------------------------------------- # -- End of 5.5 tests. # ----------------------------------------------------------------- diff --git a/mysql-test/t/table_elim.test b/mysql-test/t/table_elim.test index 24f48206013..717aecb42e2 100644 --- a/mysql-test/t/table_elim.test +++ b/mysql-test/t/table_elim.test @@ -534,12 +534,12 @@ INSERT IGNORE INTO t1 VALUES (0,'g'); CREATE TABLE t3 ( a varchar(1)) ; INSERT IGNORE INTO t3 VALUES ('g'); -CREATE TABLE t2 ( a int(11) NOT NULL, PRIMARY KEY (a)) ; +CREATE TABLE t2 ( a int(11) NOT NULL, PRIMARY KEY (a)); +INSERT INTO t2 VALUES (9), (10); create view v1 as SELECT t1.* FROM t1 LEFT JOIN t2 ON ( t1.a = t2.a ) WHERE t2.a <> 0; SELECT alias1.* FROM t3 LEFT JOIN v1 as alias1 ON ( t3.a = alias1.b ); EXPLAIN SELECT alias1.* FROM t3 LEFT JOIN v1 as alias1 ON ( t3.a = alias1.b ); - drop view v1; DROP TABLE t1,t2,t3; diff --git a/mysql-test/t/view.test b/mysql-test/t/view.test index ebd68587a47..aece2000cd4 100644 --- a/mysql-test/t/view.test +++ b/mysql-test/t/view.test @@ -5505,6 +5505,66 @@ SHOW CREATE VIEW v1; drop view v1; drop table t1,t2; + +--echo # +--echo # MDEV-12099: usage of mergeable view with LEFT JOIN +--echo # that can be converted to INNER JOIN +--echo # + +create table t1 (a int, b int, key(a)) engine=myisam; +insert into t1 values + (3,20), (7,10), (2,10), (4,30), (8,70), + (7,70), (9,100), (9,60), (8,80), (7,60); + +create table t2 (c int, d int, key (c)) engine=myisam; +insert into t2 values + (50,100), (20, 200), (10,300), + (150,100), (120, 200), (110,300), + (250,100), (220, 200), (210,300); + +create table t3(e int, f int not null, key(e), unique (f)) engine=myisam; +insert into t3 values + (100, 3), (300, 5), (400, 4), (300,7), + (300,2), (600, 13), (800, 15), (700, 14), + (600, 23), (800, 25), (700, 24); + +create view v1 as + select * from t2 left join t3 on t3.e=t2.d where t3.f is not null; + +select * + from t1 left join v1 on v1.c=t1.b + where t1.a < 5; + +select * + from t1 left join ( t2 left join t3 on t3.e=t2.d ) + on t2.c=t1.b and t3.f is not null + where t1.a < 5; + +explain extended +select * + from t1 left join v1 on v1.c=t1.b + where t1.a < 5; + +explain extended +select * + from t1 left join ( t2 left join t3 on t3.e=t2.d ) + on t2.c=t1.b and t3.f is not null + where t1.a < 5; + +explain extended +select * + from t1 left join v1 on v1.c=t1.b and v1.f=t1.a + where t1.a < 5; + +explain extended +select * + from t1 left join ( t2 left join t3 on t3.e=t2.d ) + on t2.c=t1.b and t3.f=t1.a and t3.f is not null + where t1.a < 5; + +drop view v1; +drop table t1,t2,t3; + --echo # ----------------------------------------------------------------- --echo # -- End of 5.5 tests. --echo # ----------------------------------------------------------------- diff --git a/sql/sql_derived.cc b/sql/sql_derived.cc index 44395599961..20fca2de8cf 100644 --- a/sql/sql_derived.cc +++ b/sql/sql_derived.cc @@ -446,6 +446,9 @@ bool mysql_derived_merge(THD *thd, LEX *lex, TABLE_LIST *derived) { Item *expr= derived->on_expr; expr= and_conds(expr, dt_select->join ? dt_select->join->conds : 0); + if (expr) + expr->top_level_item(); + if (expr && (derived->prep_on_expr || expr != derived->on_expr)) { derived->on_expr= expr; |