summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorSergey Petrunya <psergey@askmonty.org>2011-07-15 02:58:34 +0400
committerSergey Petrunya <psergey@askmonty.org>2011-07-15 02:58:34 +0400
commit56a23357ae8e62b92b9dcdfa79336881c32f138a (patch)
tree895fdd1b527d8b6ccbff59692514a26c4c290750
parent932d51665623624fd768c5f62164b439d7cba810 (diff)
downloadmariadb-git-56a23357ae8e62b92b9dcdfa79336881c32f138a.tar.gz
BUG#803457: Wrong result with semijoin + view + outer join in maria-5.3-subqueries-mwl90
(This is not a real fix for this bug, even though it makes it to no longer repeat) - Semi-join subquery predicates, i.e. ... WHERE outer_expr IN (SELECT ...) may have null-rejecting properties, may allow to convert outer joins into inner. - When convert_subq_to_sj() injected IN-equality into parent's WHERE/ON clause, it didn't call $new_cond->top_level_item(), which would cause null-rejecting properties to be lost. - Fixed, now the mentioned outer-to-inner conversion will really take place.
-rw-r--r--mysql-test/r/subselect_sj.result36
-rw-r--r--mysql-test/r/subselect_sj2.result8
-rw-r--r--mysql-test/r/subselect_sj2_jcl6.result8
-rw-r--r--mysql-test/r/subselect_sj2_mat.result4
-rw-r--r--mysql-test/r/subselect_sj_jcl6.result54
-rw-r--r--mysql-test/t/subselect_sj.test28
-rw-r--r--sql/opt_subselect.cc2
7 files changed, 114 insertions, 26 deletions
diff --git a/mysql-test/r/subselect_sj.result b/mysql-test/r/subselect_sj.result
index 084bc515625..31f0b19f62f 100644
--- a/mysql-test/r/subselect_sj.result
+++ b/mysql-test/r/subselect_sj.result
@@ -1,5 +1,5 @@
drop table if exists t0, t1, t2, t3, t4, t10, t11, t12;
-drop view if exists v1, v2;
+drop view if exists v1, v2, v3, v4;
drop procedure if exists p1;
set @subselect_sj_tmp= @@optimizer_switch;
set optimizer_switch='semijoin=on,firstmatch=on,loosescan=on';
@@ -726,7 +726,7 @@ FROM it1 LEFT JOIN it2 ON it2.datetime_key);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY it1 index NULL int_key 4 NULL 2 Using index; Start temporary
1 PRIMARY ot1 ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
-1 PRIMARY it2 ALL NULL NULL NULL NULL 20 Using where; End temporary
+1 PRIMARY it2 ref int_key int_key 4 test.ot1.int_nokey 3 Using where; End temporary
DROP TABLE ot1, it1, it2;
# End of BUG#38075
#
@@ -1378,7 +1378,7 @@ insert into t3 values('three'),( 'four');
explain select * from t3 where t3.b in (select t2.b from t1 left join t2 on t1.a=t2.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Start temporary
-1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where
+1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
1 PRIMARY t3 ALL NULL NULL NULL NULL 8 Using where; End temporary; Using join buffer (flat, BNL join)
select * from t3 where t3.b in (select t2.b from t1 left join t2 on t1.a=t2.a);
b
@@ -1593,4 +1593,34 @@ ON (t1.f3) IN ( SELECT f4 FROM t1 )
EXECUTE st1;
f1 f3 f4 f2 f4
DROP TABLE t1,t2,t3;
+#
+# BUG#803457: Wrong result with semijoin + view + outer join in maria-5.3-subqueries-mwl90
+# (Original testcase)
+#
+CREATE TABLE t1 (f1 int, f2 int );
+INSERT INTO t1 VALUES (2,0),(4,0),(0,NULL);
+CREATE TABLE t2 (f2 int, f3 int );
+INSERT INTO t2 VALUES (NULL,NULL),(0,0);
+CREATE TABLE t3 ( f1 int, f3 int );
+INSERT INTO t3 VALUES (2,0),(4,0),(0,NULL),(4,0),(8,0);
+CREATE TABLE t4 ( f2 int, KEY (f2) );
+INSERT INTO t4 VALUES (0),(NULL);
+CREATE VIEW v4 AS SELECT DISTINCT f2 FROM t4 ;
+# The following must not have outer joins:
+explain extended
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+id select_type table type possible_keys key key_len ref rows filtered Extra
+1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where
+1 PRIMARY t4 ref f2 f2 5 test.t2.f3 2 100.00 Using index; FirstMatch(t2)
+1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
+1 PRIMARY t3 ALL NULL NULL NULL NULL 5 100.00 Using where; Using join buffer (flat, BNL join)
+Warnings:
+Note 1003 select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t3`.`f3` AS `f3` from `test`.`t1` semi join (`test`.`t4`) join `test`.`t2` join `test`.`t3` where ((`test`.`t1`.`f2` = `test`.`t2`.`f2`) and (`test`.`t3`.`f1` = `test`.`t1`.`f1`) and (`test`.`t4`.`f2` = `test`.`t2`.`f3`))
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+f1 f2 f3 f3
+2 0 0 0
+4 0 0 0
+4 0 0 0
+drop view v4;
+drop table t1, t2, t3, t4;
set optimizer_switch=@subselect_sj_tmp;
diff --git a/mysql-test/r/subselect_sj2.result b/mysql-test/r/subselect_sj2.result
index e71486ab4a8..036fd6ebb48 100644
--- a/mysql-test/r/subselect_sj2.result
+++ b/mysql-test/r/subselect_sj2.result
@@ -267,10 +267,10 @@ explain select *
from t0 where a in
(select t2.a+t3.a from t1 left join (t2 join t3) on t2.a=t1.a and t3.a=t1.a);
id select_type table type possible_keys key key_len ref rows Extra
-1 PRIMARY t0 ALL NULL NULL NULL NULL 10 Start temporary
-1 PRIMARY t1 index NULL a 5 NULL 10 Using index; Using join buffer (flat, BNL join)
-1 PRIMARY t2 ref a a 5 test.t1.a 1 Using where; Using index
-1 PRIMARY t3 ref a a 5 test.t1.a 1 Using where; Using index; End temporary
+1 PRIMARY t0 ALL NULL NULL NULL NULL 10
+1 PRIMARY t1 index a a 5 NULL 10 Using where; Using index
+1 PRIMARY t2 ref a a 5 test.t1.a 1 Using index
+1 PRIMARY t3 ref a a 5 test.t1.a 1 Using index; FirstMatch(t0)
drop table t0, t1,t2,t3;
CREATE TABLE t1 (
ID int(11) NOT NULL auto_increment,
diff --git a/mysql-test/r/subselect_sj2_jcl6.result b/mysql-test/r/subselect_sj2_jcl6.result
index ef3d7700704..eefafbb1a88 100644
--- a/mysql-test/r/subselect_sj2_jcl6.result
+++ b/mysql-test/r/subselect_sj2_jcl6.result
@@ -275,10 +275,10 @@ explain select *
from t0 where a in
(select t2.a+t3.a from t1 left join (t2 join t3) on t2.a=t1.a and t3.a=t1.a);
id select_type table type possible_keys key key_len ref rows Extra
-1 PRIMARY t0 ALL NULL NULL NULL NULL 10 Start temporary
-1 PRIMARY t1 index NULL a 5 NULL 10 Using index; Using join buffer (flat, BNL join)
-1 PRIMARY t2 ref a a 5 test.t1.a 1 Using where; Using index
-1 PRIMARY t3 ref a a 5 test.t1.a 1 Using where; Using index; End temporary
+1 PRIMARY t0 ALL NULL NULL NULL NULL 10
+1 PRIMARY t1 index a a 5 NULL 10 Using where; Using index
+1 PRIMARY t2 ref a a 5 test.t1.a 1 Using index
+1 PRIMARY t3 ref a a 5 test.t1.a 1 Using index; FirstMatch(t0)
drop table t0, t1,t2,t3;
CREATE TABLE t1 (
ID int(11) NOT NULL auto_increment,
diff --git a/mysql-test/r/subselect_sj2_mat.result b/mysql-test/r/subselect_sj2_mat.result
index c680fd2ba67..5a5d0065d64 100644
--- a/mysql-test/r/subselect_sj2_mat.result
+++ b/mysql-test/r/subselect_sj2_mat.result
@@ -279,8 +279,8 @@ from t0 where a in
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t0 ALL NULL NULL NULL NULL 10
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 9 func 1
-2 SUBQUERY t1 index NULL a 5 NULL 10 Using index
-2 SUBQUERY t2 ref a a 5 test.t1.a 1 Using where; Using index
+2 SUBQUERY t1 index a a 5 NULL 10 Using where; Using index
+2 SUBQUERY t2 ref a a 5 test.t1.a 1 Using index
2 SUBQUERY t3 ref a a 5 test.t1.a 1 Using index
drop table t0, t1,t2,t3;
CREATE TABLE t1 (
diff --git a/mysql-test/r/subselect_sj_jcl6.result b/mysql-test/r/subselect_sj_jcl6.result
index b237a90f26c..382a766e7a2 100644
--- a/mysql-test/r/subselect_sj_jcl6.result
+++ b/mysql-test/r/subselect_sj_jcl6.result
@@ -9,7 +9,7 @@ show variables like 'join_cache_level';
Variable_name Value
join_cache_level 6
drop table if exists t0, t1, t2, t3, t4, t10, t11, t12;
-drop view if exists v1, v2;
+drop view if exists v1, v2, v3, v4;
drop procedure if exists p1;
set @subselect_sj_tmp= @@optimizer_switch;
set optimizer_switch='semijoin=on,firstmatch=on,loosescan=on';
@@ -713,22 +713,22 @@ WHERE int_nokey IN (SELECT it2.int_key
FROM it1 LEFT JOIN it2 ON it2.datetime_key);
int_key
0
-2
-0
-7
+5
9
9
-5
+7
+2
+8
+0
2
0
0
0
-3
-7
-7
-8
0
5
+7
+7
+3
EXPLAIN
SELECT int_key FROM ot1
WHERE int_nokey IN (SELECT it2.int_key
@@ -736,7 +736,7 @@ FROM it1 LEFT JOIN it2 ON it2.datetime_key);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY it1 index NULL int_key 4 NULL 2 Using index; Start temporary
1 PRIMARY ot1 ALL NULL NULL NULL NULL 20 Using join buffer (flat, BNL join)
-1 PRIMARY it2 ALL NULL NULL NULL NULL 20 Using where; End temporary; Using join buffer (incremental, BNL join)
+1 PRIMARY it2 ref int_key int_key 4 test.ot1.int_nokey 3 Using where; End temporary; Using join buffer (incremental, BKA join); Key-ordered Rowid-ordered scan
DROP TABLE ot1, it1, it2;
# End of BUG#38075
#
@@ -1467,8 +1467,8 @@ explain
select * from t0 where a in (select t1.a from t1 left join t2 on t1.a=t2.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t0 ALL NULL NULL NULL NULL 2
-1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
-1 PRIMARY t2 ALL NULL NULL NULL NULL 1 Using where; FirstMatch(t0)
+1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where; Start temporary
+1 PRIMARY t2 ALL NULL NULL NULL NULL 1 Using where; End temporary
select * from t0 where a in (select t1.a from t1 left join t2 on t1.a=t2.a);
a
1
@@ -1603,6 +1603,36 @@ ON (t1.f3) IN ( SELECT f4 FROM t1 )
EXECUTE st1;
f1 f3 f4 f2 f4
DROP TABLE t1,t2,t3;
+#
+# BUG#803457: Wrong result with semijoin + view + outer join in maria-5.3-subqueries-mwl90
+# (Original testcase)
+#
+CREATE TABLE t1 (f1 int, f2 int );
+INSERT INTO t1 VALUES (2,0),(4,0),(0,NULL);
+CREATE TABLE t2 (f2 int, f3 int );
+INSERT INTO t2 VALUES (NULL,NULL),(0,0);
+CREATE TABLE t3 ( f1 int, f3 int );
+INSERT INTO t3 VALUES (2,0),(4,0),(0,NULL),(4,0),(8,0);
+CREATE TABLE t4 ( f2 int, KEY (f2) );
+INSERT INTO t4 VALUES (0),(NULL);
+CREATE VIEW v4 AS SELECT DISTINCT f2 FROM t4 ;
+# The following must not have outer joins:
+explain extended
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+id select_type table type possible_keys key key_len ref rows filtered Extra
+1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where
+1 PRIMARY t4 ref f2 f2 5 test.t2.f3 2 100.00 Using index; FirstMatch(t2)
+1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
+1 PRIMARY t3 ALL NULL NULL NULL NULL 5 100.00 Using where; Using join buffer (incremental, BNL join)
+Warnings:
+Note 1003 select `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3`,`test`.`t3`.`f3` AS `f3` from `test`.`t1` semi join (`test`.`t4`) join `test`.`t2` join `test`.`t3` where ((`test`.`t1`.`f2` = `test`.`t2`.`f2`) and (`test`.`t3`.`f1` = `test`.`t1`.`f1`) and (`test`.`t4`.`f2` = `test`.`t2`.`f3`))
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+f1 f2 f3 f3
+2 0 0 0
+4 0 0 0
+4 0 0 0
+drop view v4;
+drop table t1, t2, t3, t4;
set optimizer_switch=@subselect_sj_tmp;
#
# BUG#49129: Wrong result with IN-subquery with join_cache_level=6 and firstmatch=off
diff --git a/mysql-test/t/subselect_sj.test b/mysql-test/t/subselect_sj.test
index 2a0197a3047..4f9331be476 100644
--- a/mysql-test/t/subselect_sj.test
+++ b/mysql-test/t/subselect_sj.test
@@ -3,7 +3,7 @@
#
--disable_warnings
drop table if exists t0, t1, t2, t3, t4, t10, t11, t12;
-drop view if exists v1, v2;
+drop view if exists v1, v2, v3, v4;
drop procedure if exists p1;
--enable_warnings
@@ -1459,6 +1459,32 @@ ON (t1.f3) IN ( SELECT f4 FROM t1 )
EXECUTE st1;
DROP TABLE t1,t2,t3;
+--echo #
+--echo # BUG#803457: Wrong result with semijoin + view + outer join in maria-5.3-subqueries-mwl90
+--echo # (Original testcase)
+--echo #
+
+CREATE TABLE t1 (f1 int, f2 int );
+INSERT INTO t1 VALUES (2,0),(4,0),(0,NULL);
+
+CREATE TABLE t2 (f2 int, f3 int );
+INSERT INTO t2 VALUES (NULL,NULL),(0,0);
+
+CREATE TABLE t3 ( f1 int, f3 int );
+INSERT INTO t3 VALUES (2,0),(4,0),(0,NULL),(4,0),(8,0);
+
+CREATE TABLE t4 ( f2 int, KEY (f2) );
+INSERT INTO t4 VALUES (0),(NULL);
+
+CREATE VIEW v4 AS SELECT DISTINCT f2 FROM t4 ;
+
+--echo # The following must not have outer joins:
+explain extended
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+SELECT * FROM t1 NATURAL LEFT JOIN (t2, t3) WHERE t2.f3 IN (SELECT * FROM t4);
+
+drop view v4;
+drop table t1, t2, t3, t4;
# The following command must be the last one the file
set optimizer_switch=@subselect_sj_tmp;
diff --git a/sql/opt_subselect.cc b/sql/opt_subselect.cc
index 9fb392c20f4..48c295b907d 100644
--- a/sql/opt_subselect.cc
+++ b/sql/opt_subselect.cc
@@ -1306,6 +1306,7 @@ static bool convert_subq_to_sj(JOIN *parent_join, Item_in_subselect *subq_pred)
{
emb_tbl_nest->on_expr= and_items(emb_tbl_nest->on_expr,
sj_nest->sj_on_expr);
+ emb_tbl_nest->on_expr->top_level_item();
if (!emb_tbl_nest->on_expr->fixed)
emb_tbl_nest->on_expr->fix_fields(parent_join->thd,
&emb_tbl_nest->on_expr);
@@ -1314,6 +1315,7 @@ static bool convert_subq_to_sj(JOIN *parent_join, Item_in_subselect *subq_pred)
{
/* Inject into the WHERE */
parent_join->conds= and_items(parent_join->conds, sj_nest->sj_on_expr);
+ parent_join->conds->top_level_item();
/*
fix_fields must update the properties (e.g. st_select_lex::cond_count of
the correct select_lex.