From a6037394e3a33e6a8294ee0c573d623982a4535a Mon Sep 17 00:00:00 2001 From: unknown <timour@askmonty.org> Date: Tue, 9 Aug 2011 10:28:57 +0300 Subject: [PATCH] Fix bug lp:817384 This bug is a special case of lp:813447. Analysis: Constant optimization finds that the condition t2.a = 1 can be used to access the primary key of table 't2'. As a result both outer table t1,t2 are considered as constant when we reach the execution phase. At the same time, during constant optimization, the IN predicate is not evaluated because it is expensive. When execution of the outer query reaches do_select(), control flow enter the branch: if (join->table_count == join->const_tables) { ... } This branch checks only the WHERE and HAVING clauses, but doesn't check the ON clauses of the query. Since the IN predicate was not evaluated during optimization, it is not evaluated at all, thus execution doesn't detect that the ON clause is FALSE. Solution: Similar to the patch for bug lp:813447, exclude system tables from constant substitution based on unique key lookups if there is an expensive ON condition on the inner table. --- mysql-test/r/join_outer.result | 32 +++++++++++++++++++++++ mysql-test/r/join_outer_jcl6.result | 32 +++++++++++++++++++++++ mysql-test/r/subselect.result | 4 +-- mysql-test/r/subselect_no_mat.result | 4 +-- mysql-test/r/subselect_no_opts.result | 4 +-- mysql-test/r/subselect_no_semijoin.result | 4 +-- mysql-test/r/subselect_scache.result | 4 +-- mysql-test/suite/pbxt/r/subselect.result | 4 +-- mysql-test/t/join_outer.test | 27 +++++++++++++++++++ sql/sql_select.cc | 4 ++- 10 files changed, 106 insertions(+), 13 deletions(-) diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result index b5d26970d3..cc3723734d 100644 --- a/mysql-test/r/join_outer.result +++ b/mysql-test/r/join_outer.result @@ -1561,3 +1561,35 @@ id select_type table type possible_keys key key_len ref rows filtered Extra Warnings: Note 1003 select `test`.`t2`.`a` AS `a` from `test`.`t1` left join `test`.`t2` on(<in_optimizer>(6,<exists>(select `test`.`t3`.`a` from `test`.`t3` where (6 = `test`.`t3`.`a`)))) where 1 DROP TABLE t1,t2,t3; +# +# LP bug #817384 Wrong result with outer join + subquery in ON +# clause +unique key +# +CREATE TABLE t1 ( c int NOT NULL , b char(1) NOT NULL ) ; +INSERT INTO t1 VALUES (1,'b'); +CREATE TABLE t2 ( a int NOT NULL , b char(1) NOT NULL , PRIMARY KEY (a)) ; +INSERT INTO t2 VALUES (1,'a'); +create table t3 (c1 char(1), c2 char(2)); +insert into t3 values ('c','d'); +insert into t3 values ('c','d'); +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 +1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 const 1 Using where +2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where +SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); +b +NULL +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 +1 PRIMARY t2 const PRIMARY PRIMARY 4 const 1 Using where +2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where +SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; +b +NULL +DROP TABLE t1,t2,t3; diff --git a/mysql-test/r/join_outer_jcl6.result b/mysql-test/r/join_outer_jcl6.result index 3f3f154399..493b5542eb 100644 --- a/mysql-test/r/join_outer_jcl6.result +++ b/mysql-test/r/join_outer_jcl6.result @@ -1570,6 +1570,38 @@ id select_type table type possible_keys key key_len ref rows filtered Extra Warnings: Note 1003 select `test`.`t2`.`a` AS `a` from `test`.`t1` left join `test`.`t2` on(<in_optimizer>(6,<exists>(select `test`.`t3`.`a` from `test`.`t3` where (6 = `test`.`t3`.`a`)))) where 1 DROP TABLE t1,t2,t3; +# +# LP bug #817384 Wrong result with outer join + subquery in ON +# clause +unique key +# +CREATE TABLE t1 ( c int NOT NULL , b char(1) NOT NULL ) ; +INSERT INTO t1 VALUES (1,'b'); +CREATE TABLE t2 ( a int NOT NULL , b char(1) NOT NULL , PRIMARY KEY (a)) ; +INSERT INTO t2 VALUES (1,'a'); +create table t3 (c1 char(1), c2 char(2)); +insert into t3 values ('c','d'); +insert into t3 values ('c','d'); +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 +1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 const 1 Using where +2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where +SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); +b +NULL +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 +1 PRIMARY t2 const PRIMARY PRIMARY 4 const 1 Using where +2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where +SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; +b +NULL +DROP TABLE t1,t2,t3; set join_cache_level=default; show variables like 'join_cache_level'; Variable_name Value diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 8e1679feab..84882a3bc2 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -2960,7 +2960,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2972,7 +2972,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/r/subselect_no_mat.result b/mysql-test/r/subselect_no_mat.result index 274954f59e..3352386737 100644 --- a/mysql-test/r/subselect_no_mat.result +++ b/mysql-test/r/subselect_no_mat.result @@ -2965,7 +2965,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2977,7 +2977,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/r/subselect_no_opts.result b/mysql-test/r/subselect_no_opts.result index 92f9890ab2..d6eb79ba10 100644 --- a/mysql-test/r/subselect_no_opts.result +++ b/mysql-test/r/subselect_no_opts.result @@ -2961,7 +2961,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2973,7 +2973,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/r/subselect_no_semijoin.result b/mysql-test/r/subselect_no_semijoin.result index ce1d97a77f..f3bb3f6ff4 100644 --- a/mysql-test/r/subselect_no_semijoin.result +++ b/mysql-test/r/subselect_no_semijoin.result @@ -2961,7 +2961,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2973,7 +2973,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/r/subselect_scache.result b/mysql-test/r/subselect_scache.result index db7a35b5e1..7b1bbf77a3 100644 --- a/mysql-test/r/subselect_scache.result +++ b/mysql-test/r/subselect_scache.result @@ -2964,7 +2964,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2976,7 +2976,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 system PRIMARY NULL NULL NULL 1 -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 2 Using index condition SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/suite/pbxt/r/subselect.result b/mysql-test/suite/pbxt/r/subselect.result index b5aa831718..b8b63ed585 100644 --- a/mysql-test/suite/pbxt/r/subselect.result +++ b/mysql-test/suite/pbxt/r/subselect.result @@ -2954,7 +2954,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c DESC, t2.b DESC LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 const PRIMARY PRIMARY 4 const 1 Using index -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 1 Using where SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' @@ -2966,7 +2966,7 @@ ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' ORDER BY t2.c, t2.b LIMIT 1) WHERE t1.a = 10; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 const PRIMARY PRIMARY 4 const 1 Using index -1 PRIMARY r const PRIMARY PRIMARY 4 const 1 +1 PRIMARY r eq_ref PRIMARY PRIMARY 4 const 1 Using where 2 DEPENDENT SUBQUERY t2 range b b 40 NULL 1 Using where SELECT sql_no_cache t1.a, r.a, r.b FROM t1 LEFT JOIN t2 r ON r.a = (SELECT t2.a FROM t2 WHERE t2.c = t1.a AND t2.b <= '359899' diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test index 71a983bd56..253808c4eb 100644 --- a/mysql-test/t/join_outer.test +++ b/mysql-test/t/join_outer.test @@ -1127,3 +1127,30 @@ SELECT t2.a FROM t1 LEFT JOIN t2 ON (6) IN (SELECT a FROM t3); DROP TABLE t1,t2,t3; +--echo # +--echo # LP bug #817384 Wrong result with outer join + subquery in ON +--echo # clause +unique key +--echo # + +CREATE TABLE t1 ( c int NOT NULL , b char(1) NOT NULL ) ; +INSERT INTO t1 VALUES (1,'b'); + +CREATE TABLE t2 ( a int NOT NULL , b char(1) NOT NULL , PRIMARY KEY (a)) ; +INSERT INTO t2 VALUES (1,'a'); + +create table t3 (c1 char(1), c2 char(2)); +insert into t3 values ('c','d'); +insert into t3 values ('c','d'); + + +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); +SELECT t2.b +FROM t1 LEFT JOIN t2 ON t1.c = t2.a AND ( t2.b , t1.b ) IN (SELECT * from t3); + +EXPLAIN SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; +SELECT t2.b +FROM t1 LEFT JOIN t2 ON (t2.b) IN (SELECT c2 from t3) AND t2.a = 1; + +DROP TABLE t1,t2,t3; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index d8d91fbb07..5cc8078b9f 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3330,7 +3330,9 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list, { if (table->key_info[key].flags & HA_NOSAME) { - if (const_ref == eq_part) + if (const_ref == eq_part && + !((outer_join & table->map) && + (*s->on_expr_ref)->is_expensive())) { // Found everything for ref. int tmp; ref_changed = 1; -- 2.30.9