diff options
32 files changed, 6779 insertions, 982 deletions
diff --git a/mysql-test/include/check_shared_row_lock.inc b/mysql-test/include/check_shared_row_lock.inc index efc7e13b3aa..1c9d9b0c3c6 100644 --- a/mysql-test/include/check_shared_row_lock.inc +++ b/mysql-test/include/check_shared_row_lock.inc @@ -33,7 +33,8 @@ connection default; # least it acquires S-locks on some of rows. let $wait_condition= select count(*) = 1 from information_schema.processlist - where state in ("Sending data","statistics", "preparing") and + where state in ("Sending data","statistics", "preparing", "updating", + "executing", "Searching rows for update") and info = "$wait_statement"; --source include/wait_condition.inc diff --git a/mysql-test/include/subselect_mat_cost.inc b/mysql-test/include/subselect_mat_cost.inc new file mode 100644 index 00000000000..04b116e9527 --- /dev/null +++ b/mysql-test/include/subselect_mat_cost.inc @@ -0,0 +1,152 @@ +-- echo +-- echo /* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +-- echo +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +-- echo +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; + +-- echo +-- echo /* +-- echo B. "Natural" examples of subqueries without grouping that +-- echo cannot be flattened into semijoin. +-- echo */ + +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +-- echo +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +-- echo UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +-- echo +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +-- echo +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); + +-- echo +-- echo /* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +-- echo +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +-- echo +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +-- echo +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +-- echo +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +-- echo +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); + +-- echo +-- echo /* +-- echo D. Subqueries for which materialization is not possible, and the +-- echo optimizer reverts to in-to-exists. +-- echo */ +# The first two cases are rejected during the prepare phase by the procedure +# subquery_types_allow_materialization(). +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +-- echo +# The following two subqueries return the result of a string function with a +# blob argument, where the return type may be != blob. These are rejected during +# cost-based optimization when attempting to create a temporary table. +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +-- echo + + +-- echo +-- echo /* E. Edge cases. */ +-- echo + +-- echo /* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +--error ER_ILLEGAL_SUBQUERY_OPTIMIZER_SWITCHES +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +set @@optimizer_switch = @save_optimizer_switch; + +-- echo /* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +select '1 - 03' in (select b1 from t2 where b1 > '0'); + +-- echo /* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +-- echo UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); + +-- echo /* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; + +-- echo /* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +-- echo TODO this test produces wrong result due to missing logic to handle the case +-- echo when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +select a1 from t1 where a1 in (select max(b1) from t2); +-- echo +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); + +-- echo /* E.6 make_join_select detects impossible WHERE. * + +-- echo TODO + +-- echo /* E.7 constant optimization detects "no matching row in const table". */ + +-- echo TODO + +-- echo /* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); + +-- echo +-- echo /* F. UPDATE/DELETE with subqueries. */ +-- echo + +-- echo TODO +-- echo diff --git a/mysql-test/r/subselect3.result b/mysql-test/r/subselect3.result index 78a75776573..dbfb035eadc 100644 --- a/mysql-test/r/subselect3.result +++ b/mysql-test/r/subselect3.result @@ -841,11 +841,16 @@ x ROW(11, 12) = (SELECT MAX(x), 22) ROW(11, 12) IN (SELECT MAX(x), 22) 1 0 0 2 0 0 11 0 0 -# 2nd and 3rd columns should be same for x == 11 only +# 2nd and 3rd columns should be same +EXPLAIN SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; x ROW(11, 12) = (SELECT MAX(x), 12) ROW(11, 12) IN (SELECT MAX(x), 12) -1 0 1 -2 0 1 +1 0 0 +2 0 0 11 1 1 DROP TABLE t1; # both columns should be same diff --git a/mysql-test/r/subselect3_jcl6.result b/mysql-test/r/subselect3_jcl6.result index f866f1c2aa9..ba7e6871a93 100644 --- a/mysql-test/r/subselect3_jcl6.result +++ b/mysql-test/r/subselect3_jcl6.result @@ -848,11 +848,16 @@ x ROW(11, 12) = (SELECT MAX(x), 22) ROW(11, 12) IN (SELECT MAX(x), 22) 1 0 0 2 0 0 11 0 0 -# 2nd and 3rd columns should be same for x == 11 only +# 2nd and 3rd columns should be same +EXPLAIN SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; x ROW(11, 12) = (SELECT MAX(x), 12) ROW(11, 12) IN (SELECT MAX(x), 12) -1 0 1 -2 0 1 +1 0 0 +2 0 0 11 1 1 DROP TABLE t1; # both columns should be same diff --git a/mysql-test/r/subselect4.result b/mysql-test/r/subselect4.result index 8547a180d49..4f90045e60a 100644 --- a/mysql-test/r/subselect4.result +++ b/mysql-test/r/subselect4.result @@ -483,3 +483,266 @@ pk # Restore old value for Index condition pushdown SET SESSION engine_condition_pushdown=@old_icp; DROP TABLE t1,t2; +# +# LP BUG#641203 Query returns rows where no result is expected (impossible WHERE) +# +CREATE TABLE t1 (c1 varchar(1) DEFAULT NULL); +CREATE TABLE t2 (c1 varchar(1) DEFAULT NULL); +INSERT INTO t2 VALUES ('k'), ('d'); +CREATE TABLE t3 (c1 varchar(1) DEFAULT NULL); +INSERT INTO t3 VALUES ('a'), ('b'), ('c'); +CREATE TABLE t4 (c1 varchar(1) primary key); +INSERT INTO t4 VALUES ('k'), ('d'); +EXPLAIN +SELECT * FROM t1 RIGHT JOIN t2 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 2 Using where +SELECT * FROM t1 RIGHT JOIN t2 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +c1 c1 +EXPLAIN +SELECT * FROM t2 LEFT JOIN t1 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 2 Using where +SELECT * FROM t2 LEFT JOIN t1 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +c1 c1 +EXPLAIN +SELECT * FROM (t2 LEFT JOIN t1 ON t1.c1) LEFT JOIN t3 on t3.c1 WHERE 's' IN (SELECT c1 FROM t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 2 Using where +SELECT * FROM (t2 LEFT JOIN t1 ON t1.c1) LEFT JOIN t3 on t3.c1 WHERE 's' IN (SELECT c1 FROM t2); +c1 c1 c1 +EXPLAIN +SELECT * FROM t4 LEFT JOIN t2 ON t4.c1 WHERE 's' IN (SELECT c1 FROM t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 2 Using where +SELECT * FROM t4 LEFT JOIN t2 ON t4.c1 WHERE 's' IN (SELECT c1 FROM t2); +c1 c1 +drop table t1, t2, t3, t4; +# +# LP BUG#675981 Assertion `cache != __null' failed in sub_select_cache() +# on EXPLAIN +# +CREATE TABLE t1 (f1 int,f2 int) ; +INSERT IGNORE INTO t1 VALUES ('2','5'),('2',NULL); +CREATE TABLE t2 (f1 int, f5 int) ; +INSERT IGNORE INTO t2 VALUES (1,0); +CREATE TABLE t3 (f4 int) ; +INSERT IGNORE INTO t3 VALUES (0),(0); +set @@optimizer_switch='in_to_exists=on,materialization=off,semijoin=off'; +EXPLAIN +SELECT * FROM t2 +WHERE f1 IN (SELECT t1.f2 FROM t1 JOIN t3 ON t3.f4); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where; Using join buffer +drop table t1, t2, t3; +# +# LP BUG#680005 Second assertion `cache != __null' failed in +# sub_select_cache() on EXPLAIN +# +CREATE TABLE t1 (f1 int,f2 int,f4 int,f6 int,KEY (f4)) ; +INSERT IGNORE INTO t1 VALUES +('1','5','1','0'),('2','1','1','0'),('2','2','2','0'),('0',NULL,'0','0'), +('2','1','2','0'),('2','0','0','0'),('2','2','2','0'),('2','8','2','0'), +('2','7','2','0'),('2','5','2','0'),('2',NULL,'1','0'); +CREATE TABLE t2 (f3 int) ; +INSERT IGNORE INTO t2 VALUES ('7'); +CREATE TABLE t3 (f3 int) ; +INSERT IGNORE INTO t3 VALUES ('2'); +EXPLAIN +SELECT t1.f4 +FROM t2 JOIN t1 ON t1.f6 +WHERE +( t1.f2 ) IN (SELECT SUBQUERY2_t1.f3 +FROM t3 AS SUBQUERY2_t1 +JOIN +(t1 AS SUBQUERY2_t2 +JOIN +t1 AS SUBQUERY2_t3 ON SUBQUERY2_t3.f1) +ON SUBQUERY2_t3.f2) +GROUP BY t1.f4 ORDER BY t1.f1 LIMIT 10; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 Using temporary; Using filesort +1 PRIMARY t1 index NULL f4 5 NULL 10 Using where +2 DEPENDENT SUBQUERY SUBQUERY2_t1 system NULL NULL NULL NULL 1 +2 DEPENDENT SUBQUERY SUBQUERY2_t2 index NULL f4 5 NULL 11 Using where; Using index +2 DEPENDENT SUBQUERY SUBQUERY2_t3 ALL NULL NULL NULL NULL 11 Using where; Using join buffer +drop table t1, t2, t3; +# +# LP BUG#680038 bool close_thread_table(THD*, TABLE**): +# Assertion `table->key_read == 0' failed in EXPLAIN +# +CREATE TABLE t1 (f1 int,f3 int,f4 int) ; +INSERT IGNORE INTO t1 VALUES (NULL,1,0); +CREATE TABLE t2 (f2 int,f4 int,f5 int) ; +INSERT IGNORE INTO t2 VALUES (8,0,0),(5,0,0); +CREATE TABLE t3 (f4 int,KEY (f4)) ; +INSERT IGNORE INTO t3 VALUES (0),(0); +set @@optimizer_switch='semijoin=off'; +EXPLAIN +SELECT * FROM t1 WHERE +(SELECT f2 FROM t2 +WHERE f4 <= ALL +(SELECT SQ1_t1.f4 +FROM t3 AS SQ1_t1 JOIN t3 AS SQ1_t3 ON SQ1_t3.f4 +GROUP BY SQ1_t1.f4)); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 system NULL NULL NULL NULL 1 +2 SUBQUERY t2 ALL NULL NULL NULL NULL 2 Using where +3 SUBQUERY SQ1_t1 index NULL f4 5 NULL 2 Using index; Using temporary; Using filesort +3 SUBQUERY SQ1_t3 index NULL f4 5 NULL 2 Using where; Using index; Using join buffer +drop table t1, t2, t3; +# +# BUG#52317: Assertion failing in Field_varstring::store() +# at field.cc:6833 +# +CREATE TABLE t1 (i INTEGER); +INSERT INTO t1 VALUES (1); +CREATE TABLE t2 (i INTEGER, KEY k(i)); +INSERT INTO t2 VALUES (1), (2); +EXPLAIN +SELECT i FROM t1 WHERE (1) NOT IN (SELECT i FROM t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t2 index_subquery k k 5 const 2 Using index +DROP TABLE t2; +DROP TABLE t1; +# +# LP BUG#680846: Crash in clear_tables() with subqueries +# +CREATE TABLE t1 (f3 int) ; +INSERT IGNORE INTO t1 VALUES (0),(0); +CREATE TABLE t2 (f1 int,f3 int,f4 varchar(32)) ; +INSERT IGNORE INTO t2 VALUES (1,0,'f'); +EXPLAIN +SELECT COUNT(t2.f3), +(SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 Using temporary; Using filesort +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT COUNT(t2.f3), +(SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; +COUNT(t2.f3) f9 +EXPLAIN +SELECT COUNT(t2.f3), +(SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT COUNT(t2.f3), +(SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; +COUNT(t2.f3) f9 +0 2 +EXPLAIN +SELECT COUNT(t2.f3), +(SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 Using temporary; Using filesort +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT COUNT(t2.f3), +(SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; +COUNT(t2.f3) f9 +EXPLAIN +SELECT COUNT(t2.f3), +(SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 system NULL NULL NULL NULL 1 +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +3 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT COUNT(t2.f3), +(SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; +COUNT(t2.f3) f9 +0 NULL +drop table t1,t2; +# +# LP BUG#682683 Crash in create_tmp_table called from +# JOIN::init_execution +# +CREATE TABLE t2 (f1 int) ; +INSERT INTO t2 VALUES (1),(2); +CREATE TABLE t1 (f1 int) ; +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 +2 SUBQUERY t1 system NULL NULL NULL NULL 0 const row not found +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +field1 +NULL +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 +2 SUBQUERY t1 system NULL NULL NULL NULL 0 const row not found +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +field1 +NULL +NULL +INSERT INTO t1 VALUES (1),(2); +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 +2 SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +ERROR 21000: Subquery returns more than 1 row +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 +2 SUBQUERY t1 ALL NULL NULL NULL NULL 2 +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +ERROR 21000: Subquery returns more than 1 row +drop table t1,t2; +# +# LP BUG#680943 Assertion `!table || (!table->read_set || +# bitmap_is_set(table->read_set, field_index))' failed with subquery +# +CREATE TABLE t1 (f1 int,f3 int) ; +INSERT IGNORE INTO t1 VALUES ('6','0'),('4','0'); +CREATE TABLE t2 (f1 int,f2 int,f3 int) ; +INSERT IGNORE INTO t2 VALUES ('6','0','0'),('2','0','0'); +SELECT f2 +FROM (SELECT * FROM t2) AS alias1 +WHERE (SELECT SQ2_t2.f1 +FROM t1 JOIN t1 AS SQ2_t2 ON SQ2_t2.f3 +WHERE SQ2_t2.f3 AND alias1.f1) +ORDER BY f3 ; +f2 +drop table t1,t2; diff --git a/mysql-test/r/subselect_cache.result b/mysql-test/r/subselect_cache.result index 7b9dc3c943f..115a80af55d 100644 --- a/mysql-test/r/subselect_cache.result +++ b/mysql-test/r/subselect_cache.result @@ -897,7 +897,7 @@ a b SUBS 5 6 1 4 5 1 7 8 NULL -9 NULL NULL +9 NULL 1 show status like "subquery_cache%"; Variable_name Value Subquery_cache_hit 0 @@ -916,7 +916,7 @@ a b SUBS 5 6 1 4 5 1 7 8 NULL -9 NULL NULL +9 NULL 1 show status like "subquery_cache%"; Variable_name Value Subquery_cache_hit 6 @@ -977,7 +977,7 @@ a b SUBS 5 6 0 4 5 0 7 8 NULL -9 NULL NULL +9 NULL 0 show status like "subquery_cache%"; Variable_name Value Subquery_cache_hit 0 @@ -996,7 +996,7 @@ a b SUBS 5 6 0 4 5 0 7 8 NULL -9 NULL NULL +9 NULL 0 show status like "subquery_cache%"; Variable_name Value Subquery_cache_hit 6 diff --git a/mysql-test/r/subselect_mat.result b/mysql-test/r/subselect_mat.result index dab00e3be19..ae23302b368 100644 --- a/mysql-test/r/subselect_mat.result +++ b/mysql-test/r/subselect_mat.result @@ -30,7 +30,7 @@ create index it3i3 on t3i (c1, c2); insert into t1i select * from t1; insert into t2i select * from t2; insert into t3i select * from t3; -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; /****************************************************************************** * Simple tests. ******************************************************************************/ @@ -176,33 +176,33 @@ a1 a2 1 - 02 2 - 02 select * from t1 where (a1, a2) in (select b1, min(b2) from t2i limit 1,1); ERROR 42000: This version of MySQL doesn't yet support 'LIMIT & IN/ALL/ANY/SOME subquery' -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; prepare st1 from "select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)"; -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; execute st1; a1 a2 1 - 01 2 - 01 1 - 02 2 - 02 -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; execute st1; a1 a2 1 - 01 2 - 01 1 - 02 2 - 02 -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; prepare st1 from "select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)"; -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; execute st1; a1 a2 1 - 01 2 - 01 1 - 02 2 - 02 -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; execute st1; a1 a2 1 - 01 2 - 01 1 - 02 2 - 02 -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain extended select * from t1 where (a1, a2) in (select b1, b2 from t2 order by b1, b2); id select_type table type possible_keys key key_len ref rows filtered Extra @@ -549,7 +549,7 @@ a1 a2 Test that BLOBs are not materialized (except when arguments of some functions). */ # force materialization to be always considered -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; set @prefix_len = 6; set @blob_len = 16; set @suffix_len = @blob_len - @prefix_len; @@ -951,7 +951,7 @@ insert into t1bit values (b'010', b'110'); insert into t2bit values (b'001', b'101'); insert into t2bit values (b'010', b'110'); insert into t2bit values (b'110', b'111'); -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain extended select bin(a1), bin(a2) from t1bit where (a1, a2) in (select b1, b2 from t2bit); @@ -994,7 +994,7 @@ drop table t1, t2, t3, t1i, t2i, t3i, columns; /****************************************************************************** * Test the cache of the left operand of IN. ******************************************************************************/ -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; create table t1 (s1 int); create table t2 (s2 int); insert into t1 values (5),(1),(0); @@ -1136,27 +1136,40 @@ drop table t2; create table t1 (a1 int key); create table t2 (b1 int); insert into t1 values (5); +Only the last query returns correct result. Filed as BUG#40037. +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away 2 SUBQUERY t2 system NULL NULL NULL NULL 0 const row not found select min(a1) from t1 where 7 in (select b1 from t2 group by b1); min(a1) -set @@optimizer_switch='default,materialization=off'; +NULL +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away 2 DEPENDENT SUBQUERY t2 system NULL NULL NULL NULL 0 const row not found select min(a1) from t1 where 7 in (select b1 from t2 group by b1); min(a1) -set @@optimizer_switch='default,semijoin=off'; +NULL +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away 2 SUBQUERY t2 system NULL NULL NULL NULL 0 const row not found select min(a1) from t1 where 7 in (select b1 from t2); min(a1) -set @@optimizer_switch='default,materialization=off'; +NULL +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; +explain select min(a1) from t1 where 7 in (select b1 from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select min(a1) from t1 where 7 in (select b1 from t2); +min(a1) +NULL +set @@optimizer_switch='materialization=off,in_to_exists=off,semijoin=on'; explain select min(a1) from t1 where 7 in (select b1 from t2); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables @@ -1167,7 +1180,7 @@ drop table t1,t2; create table t1 (a char(2), b varchar(10)); insert into t1 values ('a', 'aaa'); insert into t1 values ('aa', 'aaaa'); -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain select a,b from t1 where b in (select a from t1); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where @@ -1187,7 +1200,7 @@ INSERT INTO t1 (f1, f2) VALUES (10, 1.668); CREATE TABLE t2 LIKE t1; INSERT INTO t2 VALUES (1, 1.789); INSERT INTO t2 VALUES (13, 1.454); -SET @@optimizer_switch='default,semijoin=on,materialization=on'; +SET @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; EXPLAIN SELECT COUNT(*) FROM t1 WHERE (f1,f2) IN (SELECT f1,f2 FROM t2); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY subselect2 ALL unique_key NULL NULL NULL 2 @@ -1208,7 +1221,7 @@ PRIMARY KEY (pk) INSERT INTO t1 VALUES (1,'o','ffff','ffff','ffoo'),(2,'f','ffff','ffff','ffff'); CREATE TABLE t2 LIKE t1; INSERT INTO t2 VALUES (1,'i','iiii','iiii','iiii'),(2,'f','ffff','ffff','ffff'); -SET @@optimizer_switch='default,semijoin=on,materialization=on'; +SET @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; EXPLAIN SELECT pk FROM t1 WHERE (a) IN (SELECT a FROM t2 WHERE pk > 0); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 ALL NULL NULL NULL NULL 2 @@ -1237,7 +1250,7 @@ i 3 4 set @save_optimizer_switch=@@optimizer_switch; -set session optimizer_switch='materialization=off'; +set session optimizer_switch='materialization=off,in_to_exists=on'; select * from t1 where t1.i in (select t2.i from t2 join t3 where t2.i + t3.i = 5); i 1 diff --git a/mysql-test/r/subselect_mat_cost.result b/mysql-test/r/subselect_mat_cost.result new file mode 100644 index 00000000000..d11e2dd2ffc --- /dev/null +++ b/mysql-test/r/subselect_mat_cost.result @@ -0,0 +1,3877 @@ +drop table if exists t1, t2, t1_1024, t2_1024; +drop procedure if exists make_t1_indexes; +drop procedure if exists make_t2_indexes; +drop procedure if exists remove_t1_indexes; +drop procedure if exists remove_t2_indexes; +drop procedure if exists add_materialization_data; +drop procedure if exists delete_materialization_data; +drop procedure if exists set_all_columns_not_null; +drop procedure if exists set_all_columns_nullable; +create table t1 (a1 char(8), a2 char(8), a3 char(8), a4 int); +insert into t1 values ('1 - 00', '2 - 00', '3 - 00', 0); +insert into t1 values ('1 - 01', '2 - 01', '3 - 01', 1); +insert into t1 values ('1 - 02', '2 - 02', '3 - 02', 2); +create table t2 (b1 char(8), b2 char(8), b3 char(8), b4 int); +insert into t2 values ('1 - 01', '2 - 01', '3 - 01', 1); +insert into t2 values ('1 - 01', '2 - 01', '3 - 02', 2); +insert into t2 values ('1 - 02', '2 - 02', '3 - 03', 3); +insert into t2 values ('1 - 02', '2 - 02', '3 - 04', 4); +insert into t2 values ('1 - 03', '2 - 03', '3 - 05', 5); +create table t1_1024 (a1 blob(1024), a2 blob(1024)); +insert into t1_1024 values (concat('1 - 00', repeat('x', 1018)), concat('2 - 00', repeat('x', 1018))); +insert into t1_1024 values (concat('1 - 01', repeat('x', 1018)), concat('2 - 01', repeat('x', 1018))); +create table t2_1024 (b1 blob(1024), b2 blob(1024)); +insert into t2_1024 values (concat('1 - 01', repeat('x', 1018)), concat('2 - 01', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 02', repeat('x', 1018)), concat('2 - 02', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 03', repeat('x', 1018)), concat('2 - 03', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 04', repeat('x', 1018)), concat('2 - 04', repeat('x', 1018))); +create procedure make_t1_indexes() +begin +create index it1i1 on t1 (a1); +create index it1i2 on t1 (a2); +create index it1i3 on t1 (a1, a2); +create index it1_1024i1 on t1_1024 (a1(6)); +create index it1_1024i2 on t1_1024 (a2(6)); +create index it1_1024i3 on t1_1024 (a1(6), a2(6)); +end| +create procedure make_t2_indexes() +begin +create index it2i1 on t2 (b1); +create index it2i2 on t2 (b2); +create index it2i3 on t2 (b1, b2); +create unique index it2i4 on t2 (b1, b2, b3); +create index it2_1024i1 on t2_1024 (b1(6)); +create index it2_1024i2 on t2_1024 (b2(6)); +create index it2_1024i3 on t2_1024 (b1(6), b2(6)); +end| +create procedure remove_t1_indexes() +begin +drop index it1i1 on t1; +drop index it1i2 on t1; +drop index it1i3 on t1; +drop index it1_1024i1 on t1_1024; +drop index it1_1024i2 on t1_1024; +drop index it1_1024i3 on t1_1024; +end| +create procedure remove_t2_indexes() +begin +drop index it2i1 on t2; +drop index it2i2 on t2; +drop index it2i3 on t2; +drop index it2i4 on t2; +drop index it2_1024i1 on t2_1024; +drop index it2_1024i2 on t2_1024; +drop index it2_1024i3 on t2_1024; +end| +create procedure add_materialization_data() +begin +insert into t1 values ('1 - 03', '2 - 03', '3 - 03', 3); +insert into t1 values ('1 - 04', '2 - 04', '3 - 04', 4); +insert into t1 values ('1 - 05', '2 - 05', '3 - 05', 5); +insert into t1 values ('1 - 06', '2 - 06', '3 - 06', 6); +insert into t1 values ('1 - 07', '2 - 07', '3 - 07', 7); +insert into t1_1024 values (concat('1 - 03', repeat('x', 1018)), concat('2 - 03', repeat('x', 1018))); +end| +create procedure delete_materialization_data() +begin +delete from t1 where a1 >= '1 - 03'; +delete from t1_1024 where a1 >= '1 - 03'; +end| +create procedure set_all_columns_not_null() +begin +alter table t1 modify a1 char(8) not null, modify a2 char(8) not null, modify a3 char(8) not null; +alter table t2 modify b1 char(8) not null, modify b2 char(8) not null, modify b3 char(8) not null; +end| +create procedure set_all_columns_nullable() +begin +alter table t1 modify a1 char(8) null, modify a2 char(8) null, modify a3 char(8) null; +alter table t2 modify b1 char(8) null, modify b2 char(8) null, modify b3 char(8) null; +end| + +/****************************************************************************** +1. Both materialization and in-to-exists are ON, make a cost-based choice. +******************************************************************************/ +set @@optimizer_switch='materialization=on,in_to_exists=on'; + +/* 1.1 In-to-exists is cheaper */ +call make_t1_indexes(); +/* 1.1.1 non-indexed table access */ + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +3 DEPENDENT UNION t3 ALL NULL NULL NULL NULL 5 Using where +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 9 const 1 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 18 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 1.1.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i3 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i3 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i2 it2i2 9 func 2 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 18 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 27 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 9 const 1 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 18 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 1 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 27 NULL 1 Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 27 NULL 1 Using where; Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 27 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 const 2 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 18 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 1.1.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i4 8 func 1 Using index; Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 ref it2i4,it2i1,it2i2,it2i3 it2i4 8 func 2 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using index +2 DEPENDENT SUBQUERY t2 ref it2i4,it2i1,it2i2,it2i3 it2i4 8 func 2 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i2 it2i2 8 func 2 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 16 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 24 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 8 const 1 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 16 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 1 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 24 NULL 1 Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 24 NULL 1 Using where; Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 24 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 8 const 5 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 16 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +call set_all_columns_nullable(); + +/* 1.2 Materialization is cheaper */ +call add_materialization_data(); +call remove_t1_indexes(); +/* 1.2.1 non-indexed table access */ +call remove_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +3 DEPENDENT UNION t3 ALL NULL NULL NULL NULL 5 Using where +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 1.2.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 5 Using where; Using index +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i3 18 NULL 5 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 range it2i4,it2i1,it2i2,it2i3 it2i3 9 NULL 4 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i2 it2i2 9 NULL 5 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i3 18 NULL 5 Using where; Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 27 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ref it2i2 it2i2 9 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i4 27 NULL 5 Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 5 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range NULL it2i4 27 NULL 6 Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range NULL it2i4 27 NULL 6 Using where; Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 27 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 const 2 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 1.2.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 5 Using where; Using index +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i3 16 NULL 5 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 SUBQUERY t2 range it2i4,it2i1,it2i2,it2i3 it2i3 8 NULL 4 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i2 it2i2 8 NULL 5 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i3 16 NULL 5 Using where; Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 24 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 ref it2i2 it2i2 8 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i2,it2i3 it2i4 24 NULL 5 Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 5 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range NULL it2i4 24 NULL 6 Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range NULL it2i4 24 NULL 6 Using where; Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 24 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 8 const 5 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +call set_all_columns_nullable(); +/****************************************************************************** +2. Materialization is OFF, in-to-exists is ON, materialization is cheaper. +******************************************************************************/ +set @@optimizer_switch='materialization=off,in_to_exists=on'; +/* 2.1 non-indexed table access */ +call remove_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +3 DEPENDENT UNION t3 ALL NULL NULL NULL NULL 5 Using where +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 2.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i3 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i3 9 func 2 Using index; Using where; Full scan on NULL key +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i2 it2i2 9 func 2 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 18 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 27 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 18 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 1 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 27 NULL 1 Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 27 NULL 1 Using where; Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 27 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 const 2 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 2.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i4 8 func 1 Using index; Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 +1 - 03 1 +1 - 04 0 +1 - 05 0 +1 - 06 0 +1 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 ref it2i4,it2i1,it2i2,it2i3 it2i4 8 func 2 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 +2 DEPENDENT SUBQUERY t2 ref it2i4,it2i1,it2i2,it2i3 it2i4 8 func 2 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 +1 - 03 2 - 03 1 +1 - 04 2 - 04 0 +1 - 05 2 - 05 0 +1 - 06 2 - 06 0 +1 - 07 2 - 07 0 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i2 it2i2 8 func 2 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 16 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 +1 - 04 2 - 04 +1 - 05 2 - 05 +1 - 06 2 - 06 +1 - 07 2 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 24 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 +2 - 03 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i2,it2i3 it2i4 16 func,func 1 Using index; Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 +1 - 03 2 - 03 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 1 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 1 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 +1 - 03 2 - 03 3 - 03 3 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 24 NULL 1 Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 index NULL it2i4 24 NULL 1 Using where; Using index +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 24 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +1 - 03x 2 - 03x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 8 const 5 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +1 - 03 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +1 - 03 +1 - 04 +1 - 05 +1 - 06 +1 - 07 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 +1 - 03 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +call set_all_columns_nullable(); +/****************************************************************************** +3. Materialization is ON, in-to-exists is OFF, in-to-exists is cheaper. +******************************************************************************/ +set @@optimizer_switch='materialization=on,in_to_exists=off'; +call delete_materialization_data(); +call make_t1_indexes(); +/* 3.1 non-indexed table access */ +call remove_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +3 DEPENDENT UNION t3 ALL NULL NULL NULL NULL 5 Using where +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 9 const 1 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where; Using temporary; Using filesort +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 ALL NULL NULL NULL NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 18 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 5 Using where +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 3.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 5 Using where; Using index +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using index +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i3 9 NULL 4 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 index NULL it2i2 9 NULL 5 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 9 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 27 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 9 const 1 Using where; Using index +2 SUBQUERY t2 ref it2i2 it2i2 9 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY t2 index NULL it2i4 27 NULL 5 Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 9 NULL 5 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 18 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range NULL it2i4 27 NULL 6 Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range NULL it2i4 27 NULL 6 Using where; Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 27 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 9 const 2 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 18 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 18 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 9 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +/* 3.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); + +/* A. Subqueries in the SELECT clause. */ +explain +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 5 Using where; Using index +select a1, a1 in (select b1 from t2 where b1 > '0') from t1; +a1 a1 in (select b1 from t2 where b1 > '0') +1 - 00 0 +1 - 01 1 +1 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +explain +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using index +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i3 8 NULL 4 Using where; Using index +select a1, a2, (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') from t1; +a1 a2 (a1, a2) in (select b1, b2 from t2 where b1 > '0' and b1 < '9') +1 - 00 2 - 00 0 +1 - 01 2 - 01 1 +1 - 02 2 - 02 1 + +/* +B. "Natural" examples of subqueries without grouping that +cannot be flattened into semijoin. +*/ +explain +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 SUBQUERY t2 index NULL it2i2 8 NULL 5 Using index +select a1 from t1 where a1 in (select b2 from t2) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0') or a2 < '9'; +a1 a2 +1 - 00 2 - 00 +1 - 01 2 - 01 +1 - 02 2 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i2 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY t2 ref it2i2 it2i2 8 func 2 Using index +3 DEPENDENT UNION t3 index NULL it2i4 24 NULL 5 Using where; Using index +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a2 from t1 where a2 in (select b2 from t2 UNION select b3 from t2 as t3); +a2 +2 - 01 +2 - 02 + +explain +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref it1i1,it1i3 it1i1 8 const 1 Using where; Using index +2 SUBQUERY t2 ref it2i2 it2i2 8 const 1 Using index condition +select a1 from t1 where a1 = '1 - 02' and a1 in (select max(b1) from t2 where b2 = '2 - 02'); +a1 +1 - 02 + +explain +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i3 16 NULL 3 Using where; Using index +2 SUBQUERY t2 index NULL it2i4 24 NULL 5 Using index +select a1, a2 from t1 where (a1, a2) in (select b1, b2 from t2 order by b3); +a1 a2 +1 - 01 2 - 01 +1 - 02 2 - 02 + +/* C. Subqueries in the WHERE clause with GROUP BY. */ +explain +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i1 8 NULL 5 Using where; Using index +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 index it2i4,it2i1,it2i3 it2i3 16 NULL 5 Using where; Using index +select * from t1 where (a1, a2) in (select b1, b2 from t2 where b1 > '0' group by b1, b2 having b2 < '2 - 04'); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 +1 - 02 2 - 02 3 - 02 2 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range NULL it2i4 24 NULL 6 Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 group by b1, b2, b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +explain +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range NULL it2i4 24 NULL 6 Using where; Using index for group-by +select * from t1 where (a1, a2, a3) in (select b1, b2, b3 from t2 where b3 = '3 - 02' group by b1, b2); +a1 a2 a3 a4 + +explain +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 Using where +2 SUBQUERY t2 range it2i4,it2i1,it2i3 it2i4 24 NULL 2 Using where; Using index for group-by +select * from t1 where (a1,a2,a3) in (select b1,b2,b3 from t2 where b1 = '1 - 01' group by b1,b2,b3); +a1 a2 a3 a4 +1 - 01 2 - 01 3 - 01 1 + +/* +D. Subqueries for which materialization is not possible, and the +optimizer reverts to in-to-exists. +*/ +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i3 it2_1024i3 9 func 1 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select b1 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 index_subquery it2_1024i1,it2_1024i2,it2_1024i3 it2_1024i1 9 func 2 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select b1, b2 from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + +explain +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where a1 in (select substring(b1,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x +explain +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1024 ALL it1_1024i2 NULL NULL NULL 2 Using where +2 DEPENDENT SUBQUERY t2_1024 range it2_1024i1,it2_1024i3 it2_1024i1 9 NULL 4 Using where +select left(a1,7), left(a2,7) from t1_1024 where (a1,a2) in (select substring(b1,1,1024), substring(b2,1,1024) from t2_1024 where b1 > '0') or a2 < '9'; +left(a1,7) left(a2,7) +1 - 00x 2 - 00x +1 - 01x 2 - 01x + + +/* E. Edge cases. */ + +/* E.1 Both materialization and in_to_exists cannot be off. */ +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch = 'materialization=off,in_to_exists=off'; +select * from t1 where a1 in (select b1 from t2 where b1 > '0' group by b1); +ERROR HY000: At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'. +set @@optimizer_switch = @save_optimizer_switch; +/* E.2 Outer query without tables, always uses IN-TO-EXISTS. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY t2 index_subquery it2i4,it2i1,it2i3 it2i1 8 const 5 Using index; Using where +select '1 - 03' in (select b1 from t2 where b1 > '0'); +'1 - 03' in (select b1 from t2 where b1 > '0') +1 +/* E.3 Subqueries without tables. */ +explain +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i1,it1i2,it1i3 it1i3 16 NULL 3 Using where; Using index +Warnings: +Note 1249 Select 2 was reduced during optimization +select a1 from t1 where a1 in (select '1 - 03') or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +UNION subqueries are currently limited to only use IN-TO-EXISTS. +explain +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No tables used +3 DEPENDENT UNION NULL NULL NULL NULL NULL NULL NULL No tables used +NULL UNION RESULT <union2,3> ALL NULL NULL NULL NULL NULL +select a1 from t1 where a1 in (select '1 - 03' UNION select '1 - 02'); +a1 +1 - 02 +/* E.4 optimize_cond detects FALSE where/having clause. */ +explain +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index it1i2 it1i3 16 NULL 3 Using where; Using index +2 SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE +select a1 from t1 where a1 in (select b1 from t2 where b1 = b2 and b2 = '1 - 03' and b1 = '1 - 02' ) or a2 < '9'; +a1 +1 - 00 +1 - 01 +1 - 02 +/* E.5 opt_sum_query detects no matching min/max row or substitutes MIN/MAX with a const. */ +TODO this test produces wrong result due to missing logic to handle the case +when JOIN::optimize detects an empty subquery result. +explain +select a1 from t1 where a1 in (select max(b1) from t2); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Select tables optimized away +select a1 from t1 where a1 in (select max(b1) from t2); +a1 + +explain +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 index NULL it1i1 8 NULL 3 Using where; Using index +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL No matching min/max row +select a1 from t1 where a1 in (select max(b1) from t2 where b1 = '7 - 02'); +a1 +/* E.6 make_join_select detects impossible WHERE. * +TODO +/* E.7 constant optimization detects "no matching row in const table". */ +TODO +/* E.8 Impossible WHERE noticed after reading const tables. */ +explain +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +select '1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0'); +'1 - 03' in (select b1 from t2 where b1 > '0' and b1 < '0') +0 + +/* F. UPDATE/DELETE with subqueries. */ + +TODO + +call set_all_columns_nullable(); +drop procedure make_t1_indexes; +drop procedure make_t2_indexes; +drop procedure remove_t1_indexes; +drop procedure remove_t2_indexes; +drop procedure add_materialization_data; +drop procedure delete_materialization_data; +drop procedure set_all_columns_not_null; +drop procedure set_all_columns_nullable; +drop table t1, t2, t1_1024, t2_1024; +# +# LP BUG#643424 valgrind warning in choose_subquery_plan() +# +CREATE TABLE t1 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +c2 int(11) DEFAULT NULL, +PRIMARY KEY (pk), +KEY c2 (c2)); +INSERT INTO t1 VALUES (1,NULL,2); +INSERT INTO t1 VALUES (2,7,9); +INSERT INTO t1 VALUES (9,NULL,8); +CREATE TABLE t2 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +c2 int(11) DEFAULT NULL, +PRIMARY KEY (pk), +KEY c2 (c2)); +INSERT INTO t2 VALUES (1,1,7); +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off'; +SELECT pk FROM t1 WHERE (c2, c1) IN (SELECT c2, c2 FROM t2); +pk +set session optimizer_switch=@save_optimizer_switch; +drop table t1, t2; +# +# LP BUG#652727 Crash in create_ref_for_key() +# +CREATE TABLE t2 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +PRIMARY KEY (pk)); +INSERT INTO t2 VALUES (10,7); +INSERT INTO t2 VALUES (11,1); +INSERT INTO t2 VALUES (17,NULL); +CREATE TABLE t1 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +PRIMARY KEY (pk)); +INSERT INTO t1 VALUES (15,1); +INSERT INTO t1 VALUES (19,NULL); +CREATE TABLE t3 (c2 int(11) DEFAULT NULL, KEY c2 (c2)); +INSERT INTO t3 VALUES (1); +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off'; +SELECT c2 +FROM t3 +WHERE (2, 6) IN (SELECT t1.c1, t1.c1 FROM t1 STRAIGHT_JOIN t2 ON t2.pk = t1.pk); +c2 +set session optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3; +# +# LP BUG#641245 Crash in Item_equal::contains +# +CREATE TABLE t1 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +c2 int(11) DEFAULT NULL, +c3 varchar(1) DEFAULT NULL, +c4 varchar(1) DEFAULT NULL, +PRIMARY KEY (pk), +KEY c2 (c2), +KEY c3 (c3,c2)); +INSERT INTO t1 VALUES (10,7,8,'v','v'); +INSERT INTO t1 VALUES (11,1,9,'r','r'); +INSERT INTO t1 VALUES (12,5,9,'a','a'); +create table t1a like t1; +insert into t1a select * from t1; +create table t1b like t1; +insert into t1b select * from t1; +CREATE TABLE t2 ( +pk int(11) NOT NULL AUTO_INCREMENT, +c1 int(11) DEFAULT NULL, +c2 int(11) DEFAULT NULL, +c3 varchar(1) DEFAULT NULL, +c4 varchar(1) DEFAULT NULL, +PRIMARY KEY (pk), +KEY c2 (c2), +KEY c3 (c3,c2)); +INSERT INTO t2 VALUES (1,NULL,2,'w','w'); +INSERT INTO t2 VALUES (2,7,9,'m','m'); +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; +EXPLAIN EXTENDED SELECT pk +FROM t1 +WHERE c1 IN +(SELECT t1a.c1 +FROM (t1b JOIN t2 ON t2.c3 = t1b.c4) LEFT JOIN +t1a ON (t1a.c2 = t1b.pk AND 2) +WHERE t1.pk) ; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where +2 DEPENDENT SUBQUERY t2 index c3 c3 9 NULL 2 100.00 Using index +2 DEPENDENT SUBQUERY t1b ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer +2 DEPENDENT SUBQUERY t1a ref c2 c2 5 test.t1b.pk 2 100.00 Using where +Warnings: +Note 1276 Field or reference 'test.t1.pk' of SELECT #2 was resolved in SELECT #1 +Note 1003 select `test`.`t1`.`pk` AS `pk` from `test`.`t1` where <expr_cache><`test`.`t1`.`c1`,(`test`.`t1`.`pk` and (`test`.`t1b`.`c4` = `test`.`t2`.`c3`) and (<cache>(`test`.`t1`.`c1`) = `test`.`t1a`.`c1`))>(<in_optimizer>(`test`.`t1`.`c1`,<exists>(select `test`.`t1a`.`c1` from `test`.`t1b` join `test`.`t2` left join `test`.`t1a` on((2 and (`test`.`t1a`.`c2` = `test`.`t1b`.`pk`))) where (`test`.`t1`.`pk` and (`test`.`t1b`.`c4` = `test`.`t2`.`c3`) and (<cache>(`test`.`t1`.`c1`) = `test`.`t1a`.`c1`))))) +SELECT pk +FROM t1 +WHERE c1 IN +(SELECT t1a.c1 +FROM (t1b JOIN t2 ON t2.c3 = t1b.c4) LEFT JOIN +t1a ON (t1a.c2 = t1b.pk AND 2) +WHERE t1.pk) ; +pk +DROP TABLE t1, t1a, t1b, t2; diff --git a/mysql-test/t/subselect3.test b/mysql-test/t/subselect3.test index 2a5aa1c5429..6406032ebf2 100644 --- a/mysql-test/t/subselect3.test +++ b/mysql-test/t/subselect3.test @@ -683,7 +683,8 @@ SELECT a, ROW(11, 12) = (SELECT a, 12), ROW(11, 12) IN (SELECT a, 12) FROM t1; # The x alias is used below to workaround bug #40674. # Regression tests for sum function on outer column in subselect from dual: SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 22), ROW(11, 12) IN (SELECT MAX(x), 22) FROM t1; ---echo # 2nd and 3rd columns should be same for x == 11 only +--echo # 2nd and 3rd columns should be same +EXPLAIN SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; SELECT a AS x, ROW(11, 12) = (SELECT MAX(x), 12), ROW(11, 12) IN (SELECT MAX(x), 12) FROM t1; DROP TABLE t1; diff --git a/mysql-test/t/subselect4.test b/mysql-test/t/subselect4.test index 4329afdd384..7c030d126b3 100644 --- a/mysql-test/t/subselect4.test +++ b/mysql-test/t/subselect4.test @@ -432,3 +432,240 @@ WHERE SET SESSION engine_condition_pushdown=@old_icp; DROP TABLE t1,t2; + +--echo # +--echo # LP BUG#641203 Query returns rows where no result is expected (impossible WHERE) +--echo # + +CREATE TABLE t1 (c1 varchar(1) DEFAULT NULL); +CREATE TABLE t2 (c1 varchar(1) DEFAULT NULL); +INSERT INTO t2 VALUES ('k'), ('d'); +CREATE TABLE t3 (c1 varchar(1) DEFAULT NULL); +INSERT INTO t3 VALUES ('a'), ('b'), ('c'); +CREATE TABLE t4 (c1 varchar(1) primary key); +INSERT INTO t4 VALUES ('k'), ('d'); + +EXPLAIN +SELECT * FROM t1 RIGHT JOIN t2 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +SELECT * FROM t1 RIGHT JOIN t2 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +EXPLAIN +SELECT * FROM t2 LEFT JOIN t1 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +SELECT * FROM t2 LEFT JOIN t1 ON t1.c1 WHERE 's' IN (SELECT c1 FROM t2); +EXPLAIN +SELECT * FROM (t2 LEFT JOIN t1 ON t1.c1) LEFT JOIN t3 on t3.c1 WHERE 's' IN (SELECT c1 FROM t2); +SELECT * FROM (t2 LEFT JOIN t1 ON t1.c1) LEFT JOIN t3 on t3.c1 WHERE 's' IN (SELECT c1 FROM t2); +EXPLAIN +SELECT * FROM t4 LEFT JOIN t2 ON t4.c1 WHERE 's' IN (SELECT c1 FROM t2); +SELECT * FROM t4 LEFT JOIN t2 ON t4.c1 WHERE 's' IN (SELECT c1 FROM t2); +drop table t1, t2, t3, t4; + +--echo # +--echo # LP BUG#675981 Assertion `cache != __null' failed in sub_select_cache() +--echo # on EXPLAIN +--echo # + +CREATE TABLE t1 (f1 int,f2 int) ; +INSERT IGNORE INTO t1 VALUES ('2','5'),('2',NULL); + +CREATE TABLE t2 (f1 int, f5 int) ; +INSERT IGNORE INTO t2 VALUES (1,0); + +CREATE TABLE t3 (f4 int) ; +INSERT IGNORE INTO t3 VALUES (0),(0); + +set @@optimizer_switch='in_to_exists=on,materialization=off,semijoin=off'; +EXPLAIN +SELECT * FROM t2 +WHERE f1 IN (SELECT t1.f2 FROM t1 JOIN t3 ON t3.f4); + +drop table t1, t2, t3; + +--echo # +--echo # LP BUG#680005 Second assertion `cache != __null' failed in +--echo # sub_select_cache() on EXPLAIN +--echo # + +CREATE TABLE t1 (f1 int,f2 int,f4 int,f6 int,KEY (f4)) ; +INSERT IGNORE INTO t1 VALUES +('1','5','1','0'),('2','1','1','0'),('2','2','2','0'),('0',NULL,'0','0'), +('2','1','2','0'),('2','0','0','0'),('2','2','2','0'),('2','8','2','0'), +('2','7','2','0'),('2','5','2','0'),('2',NULL,'1','0'); + +CREATE TABLE t2 (f3 int) ; +INSERT IGNORE INTO t2 VALUES ('7'); + +CREATE TABLE t3 (f3 int) ; +INSERT IGNORE INTO t3 VALUES ('2'); + +EXPLAIN +SELECT t1.f4 +FROM t2 JOIN t1 ON t1.f6 +WHERE +( t1.f2 ) IN (SELECT SUBQUERY2_t1.f3 + FROM t3 AS SUBQUERY2_t1 + JOIN + (t1 AS SUBQUERY2_t2 + JOIN + t1 AS SUBQUERY2_t3 ON SUBQUERY2_t3.f1) + ON SUBQUERY2_t3.f2) +GROUP BY t1.f4 ORDER BY t1.f1 LIMIT 10; + +drop table t1, t2, t3; + +--echo # +--echo # LP BUG#680038 bool close_thread_table(THD*, TABLE**): +--echo # Assertion `table->key_read == 0' failed in EXPLAIN +--echo # + +CREATE TABLE t1 (f1 int,f3 int,f4 int) ; +INSERT IGNORE INTO t1 VALUES (NULL,1,0); + +CREATE TABLE t2 (f2 int,f4 int,f5 int) ; +INSERT IGNORE INTO t2 VALUES (8,0,0),(5,0,0); + +CREATE TABLE t3 (f4 int,KEY (f4)) ; +INSERT IGNORE INTO t3 VALUES (0),(0); + +set @@optimizer_switch='semijoin=off'; + +EXPLAIN +SELECT * FROM t1 WHERE +(SELECT f2 FROM t2 + WHERE f4 <= ALL + (SELECT SQ1_t1.f4 + FROM t3 AS SQ1_t1 JOIN t3 AS SQ1_t3 ON SQ1_t3.f4 + GROUP BY SQ1_t1.f4)); + +drop table t1, t2, t3; + +--echo # +--echo # BUG#52317: Assertion failing in Field_varstring::store() +--echo # at field.cc:6833 +--echo # + +CREATE TABLE t1 (i INTEGER); +INSERT INTO t1 VALUES (1); +CREATE TABLE t2 (i INTEGER, KEY k(i)); +INSERT INTO t2 VALUES (1), (2); + +EXPLAIN +SELECT i FROM t1 WHERE (1) NOT IN (SELECT i FROM t2); + +DROP TABLE t2; +DROP TABLE t1; + +--echo # +--echo # LP BUG#680846: Crash in clear_tables() with subqueries +--echo # + +CREATE TABLE t1 (f3 int) ; +INSERT IGNORE INTO t1 VALUES (0),(0); + +CREATE TABLE t2 (f1 int,f3 int,f4 varchar(32)) ; +INSERT IGNORE INTO t2 VALUES (1,0,'f'); + +EXPLAIN +SELECT COUNT(t2.f3), + (SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; + +SELECT COUNT(t2.f3), + (SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; + +EXPLAIN +SELECT COUNT(t2.f3), + (SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; + +SELECT COUNT(t2.f3), + (SELECT COUNT(f3) FROM t1 WHERE t2.f1) AS f9 +FROM t2 JOIN t1 ON t1.f3 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; + +# these queries are like the ones above, but without the ON clause, +# resulting in a different crash (failed assert) +EXPLAIN +SELECT COUNT(t2.f3), + (SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; + +SELECT COUNT(t2.f3), + (SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +GROUP BY f9; + +EXPLAIN +SELECT COUNT(t2.f3), + (SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; + +SELECT COUNT(t2.f3), + (SELECT t2.f1 FROM t1 limit 1) AS f9 +FROM t2 JOIN t1 +WHERE ('v') IN (SELECT f4 FROM t2) +ORDER BY f9; + +drop table t1,t2; + +--echo # +--echo # LP BUG#682683 Crash in create_tmp_table called from +--echo # JOIN::init_execution +--echo # + +CREATE TABLE t2 (f1 int) ; +INSERT INTO t2 VALUES (1),(2); + +CREATE TABLE t1 (f1 int) ; + +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; + +INSERT INTO t1 VALUES (1),(2); + +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +--error ER_SUBQUERY_NO_1_ROW +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 GROUP BY field1; +EXPLAIN +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; +--error ER_SUBQUERY_NO_1_ROW +SELECT (SELECT f1 FROM t1) AS field1 FROM t2 ORDER BY field1; + +drop table t1,t2; + +--echo # +--echo # LP BUG#680943 Assertion `!table || (!table->read_set || +--echo # bitmap_is_set(table->read_set, field_index))' failed with subquery +--echo # + +CREATE TABLE t1 (f1 int,f3 int) ; +INSERT IGNORE INTO t1 VALUES ('6','0'),('4','0'); + +CREATE TABLE t2 (f1 int,f2 int,f3 int) ; +INSERT IGNORE INTO t2 VALUES ('6','0','0'),('2','0','0'); + +SELECT f2 +FROM (SELECT * FROM t2) AS alias1 +WHERE (SELECT SQ2_t2.f1 + FROM t1 JOIN t1 AS SQ2_t2 ON SQ2_t2.f3 + WHERE SQ2_t2.f3 AND alias1.f1) +ORDER BY f3 ; + +drop table t1,t2; diff --git a/mysql-test/t/subselect_mat.test b/mysql-test/t/subselect_mat.test index 81a33c95424..4a7aa3cd79d 100644 --- a/mysql-test/t/subselect_mat.test +++ b/mysql-test/t/subselect_mat.test @@ -48,7 +48,7 @@ insert into t2i select * from t2; insert into t3i select * from t3; # force the use of materialization -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; /****************************************************************************** * Simple tests. @@ -111,22 +111,22 @@ select * from t1 where (a1, a2) in (select b1, min(b2) from t2i limit 1,1); # test re-optimization/re-execution with different execution methods # prepare once, exec with different modes -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; prepare st1 from "select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)"; -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; execute st1; -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; execute st1; -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; prepare st1 from "select * from t1 where (a1, a2) in (select b1, min(b2) from t2 where b1 > '0' group by b1)"; -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; execute st1; -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=on'; execute st1; -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; # materialize the result of ORDER BY # non-indexed fields @@ -327,7 +327,7 @@ select * from t1 order by (select col from columns limit 1); Test that BLOBs are not materialized (except when arguments of some functions). */ # force materialization to be always considered -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; set @prefix_len = 6; # BLOB == 16 (small blobs that could be stored in HEAP tables) @@ -680,7 +680,7 @@ insert into t2bit values (b'001', b'101'); insert into t2bit values (b'010', b'110'); insert into t2bit values (b'110', b'111'); -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain extended select bin(a1), bin(a2) from t1bit @@ -718,7 +718,7 @@ drop table t1, t2, t3, t1i, t2i, t3i, columns; /****************************************************************************** * Test the cache of the left operand of IN. ******************************************************************************/ -set @@optimizer_switch='semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; # Test that default values of Cached_item are not used for comparison create table t1 (s1 int); @@ -812,23 +812,28 @@ drop table t2; create table t1 (a1 int key); create table t2 (b1 int); insert into t1 values (5); - +-- echo Only the last query returns correct result. Filed as BUG#40037. # Query with group by, executed via materialization +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1); select min(a1) from t1 where 7 in (select b1 from t2 group by b1); # Query with group by, executed via IN=>EXISTS -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2 group by b1); select min(a1) from t1 where 7 in (select b1 from t2 group by b1); # Executed with materialization -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; +explain select min(a1) from t1 where 7 in (select b1 from t2); +select min(a1) from t1 where 7 in (select b1 from t2); +# Executed via IN=>EXISTS +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; explain select min(a1) from t1 where 7 in (select b1 from t2); select min(a1) from t1 where 7 in (select b1 from t2); # Executed with semi-join. Notice, this time we get a different result (NULL). -# This is the only correct result of all four queries. This difference is +# This is the only correct result of all five queries. This difference is # filed as BUG#40037. -set @@optimizer_switch='default,materialization=off'; +set @@optimizer_switch='materialization=off,in_to_exists=off,semijoin=on'; explain select min(a1) from t1 where 7 in (select b1 from t2); select min(a1) from t1 where 7 in (select b1 from t2); drop table t1,t2; @@ -840,7 +845,7 @@ create table t1 (a char(2), b varchar(10)); insert into t1 values ('a', 'aaa'); insert into t1 values ('aa', 'aaaa'); -set @@optimizer_switch='default,semijoin=off'; +set @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=off'; explain select a,b from t1 where b in (select a from t1); select a,b from t1 where b in (select a from t1); prepare st1 from "select a,b from t1 where b in (select a from t1)"; @@ -861,7 +866,7 @@ CREATE TABLE t2 LIKE t1; INSERT INTO t2 VALUES (1, 1.789); INSERT INTO t2 VALUES (13, 1.454); -SET @@optimizer_switch='default,semijoin=on,materialization=on'; +SET @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; EXPLAIN SELECT COUNT(*) FROM t1 WHERE (f1,f2) IN (SELECT f1,f2 FROM t2); SELECT COUNT(*) FROM t1 WHERE (f1,f2) IN (SELECT f1,f2 FROM t2); @@ -883,7 +888,7 @@ INSERT INTO t1 VALUES (1,'o','ffff','ffff','ffoo'),(2,'f','ffff','ffff','ffff'); CREATE TABLE t2 LIKE t1; INSERT INTO t2 VALUES (1,'i','iiii','iiii','iiii'),(2,'f','ffff','ffff','ffff'); -SET @@optimizer_switch='default,semijoin=on,materialization=on'; +SET @@optimizer_switch='materialization=on,in_to_exists=off,semijoin=on'; EXPLAIN SELECT pk FROM t1 WHERE (a) IN (SELECT a FROM t2 WHERE pk > 0); SELECT pk FROM t1 WHERE (a) IN (SELECT a FROM t2 WHERE pk > 0); SELECT pk FROM t1 WHERE (b,c,d) IN (SELECT b,c,d FROM t2 WHERE pk > 0); @@ -900,7 +905,7 @@ create table t3(i int); insert into t3 values (1), (2), (3), (4), (5), (6), (7), (8), (9), (10); select * from t1 where t1.i in (select t2.i from t2 join t3 where t2.i + t3.i = 5); set @save_optimizer_switch=@@optimizer_switch; -set session optimizer_switch='materialization=off'; +set session optimizer_switch='materialization=off,in_to_exists=on'; select * from t1 where t1.i in (select t2.i from t2 join t3 where t2.i + t3.i = 5); set session optimizer_switch=@save_optimizer_switch; drop table t1, t2, t3; diff --git a/mysql-test/t/subselect_mat_cost.test b/mysql-test/t/subselect_mat_cost.test new file mode 100644 index 00000000000..dcbaec791c0 --- /dev/null +++ b/mysql-test/t/subselect_mat_cost.test @@ -0,0 +1,324 @@ +# +# Tets of cost-based choice between the materialization and in-to-exists +# subquery execution strategies (MWL#89) +# + +--disable_warnings +drop table if exists t1, t2, t1_1024, t2_1024; +drop procedure if exists make_t1_indexes; +drop procedure if exists make_t2_indexes; +drop procedure if exists remove_t1_indexes; +drop procedure if exists remove_t2_indexes; +drop procedure if exists add_materialization_data; +drop procedure if exists delete_materialization_data; +drop procedure if exists set_all_columns_not_null; +drop procedure if exists set_all_columns_nullable; +--enable_warnings + +create table t1 (a1 char(8), a2 char(8), a3 char(8), a4 int); +insert into t1 values ('1 - 00', '2 - 00', '3 - 00', 0); +insert into t1 values ('1 - 01', '2 - 01', '3 - 01', 1); +insert into t1 values ('1 - 02', '2 - 02', '3 - 02', 2); + +create table t2 (b1 char(8), b2 char(8), b3 char(8), b4 int); +insert into t2 values ('1 - 01', '2 - 01', '3 - 01', 1); +insert into t2 values ('1 - 01', '2 - 01', '3 - 02', 2); +insert into t2 values ('1 - 02', '2 - 02', '3 - 03', 3); +insert into t2 values ('1 - 02', '2 - 02', '3 - 04', 4); +insert into t2 values ('1 - 03', '2 - 03', '3 - 05', 5); + +create table t1_1024 (a1 blob(1024), a2 blob(1024)); +insert into t1_1024 values (concat('1 - 00', repeat('x', 1018)), concat('2 - 00', repeat('x', 1018))); +insert into t1_1024 values (concat('1 - 01', repeat('x', 1018)), concat('2 - 01', repeat('x', 1018))); + +create table t2_1024 (b1 blob(1024), b2 blob(1024)); +insert into t2_1024 values (concat('1 - 01', repeat('x', 1018)), concat('2 - 01', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 02', repeat('x', 1018)), concat('2 - 02', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 03', repeat('x', 1018)), concat('2 - 03', repeat('x', 1018))); +insert into t2_1024 values (concat('1 - 04', repeat('x', 1018)), concat('2 - 04', repeat('x', 1018))); + +delimiter |; +create procedure make_t1_indexes() +begin + create index it1i1 on t1 (a1); + create index it1i2 on t1 (a2); + create index it1i3 on t1 (a1, a2); + create index it1_1024i1 on t1_1024 (a1(6)); + create index it1_1024i2 on t1_1024 (a2(6)); + create index it1_1024i3 on t1_1024 (a1(6), a2(6)); +end| + +create procedure make_t2_indexes() +begin + create index it2i1 on t2 (b1); + create index it2i2 on t2 (b2); + create index it2i3 on t2 (b1, b2); + create unique index it2i4 on t2 (b1, b2, b3); + create index it2_1024i1 on t2_1024 (b1(6)); + create index it2_1024i2 on t2_1024 (b2(6)); + create index it2_1024i3 on t2_1024 (b1(6), b2(6)); +end| + +create procedure remove_t1_indexes() +begin + drop index it1i1 on t1; + drop index it1i2 on t1; + drop index it1i3 on t1; + drop index it1_1024i1 on t1_1024; + drop index it1_1024i2 on t1_1024; + drop index it1_1024i3 on t1_1024; +end| + +create procedure remove_t2_indexes() +begin + drop index it2i1 on t2; + drop index it2i2 on t2; + drop index it2i3 on t2; + drop index it2i4 on t2; + drop index it2_1024i1 on t2_1024; + drop index it2_1024i2 on t2_1024; + drop index it2_1024i3 on t2_1024; +end| + +create procedure add_materialization_data() +begin +insert into t1 values ('1 - 03', '2 - 03', '3 - 03', 3); +insert into t1 values ('1 - 04', '2 - 04', '3 - 04', 4); +insert into t1 values ('1 - 05', '2 - 05', '3 - 05', 5); +insert into t1 values ('1 - 06', '2 - 06', '3 - 06', 6); +insert into t1 values ('1 - 07', '2 - 07', '3 - 07', 7); +insert into t1_1024 values (concat('1 - 03', repeat('x', 1018)), concat('2 - 03', repeat('x', 1018))); +end| + +create procedure delete_materialization_data() +begin +delete from t1 where a1 >= '1 - 03'; +delete from t1_1024 where a1 >= '1 - 03'; +end| + +create procedure set_all_columns_not_null() +begin +alter table t1 modify a1 char(8) not null, modify a2 char(8) not null, modify a3 char(8) not null; +alter table t2 modify b1 char(8) not null, modify b2 char(8) not null, modify b3 char(8) not null; +end| + +create procedure set_all_columns_nullable() +begin +alter table t1 modify a1 char(8) null, modify a2 char(8) null, modify a3 char(8) null; +alter table t2 modify b1 char(8) null, modify b2 char(8) null, modify b3 char(8) null; +end| + +delimiter ;| +-- echo + +-- echo /****************************************************************************** +-- echo 1. Both materialization and in-to-exists are ON, make a cost-based choice. +-- echo ******************************************************************************/ +set @@optimizer_switch='materialization=on,in_to_exists=on'; +-- echo +-- echo /* 1.1 In-to-exists is cheaper */ +call make_t1_indexes(); + +-- echo /* 1.1.1 non-indexed table access */ +-- source include/subselect_mat_cost.inc + +-- echo /* 1.1.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 1.1.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); +-- source include/subselect_mat_cost.inc +call set_all_columns_nullable(); + +-- echo +-- echo /* 1.2 Materialization is cheaper */ +# make materialization cheaper +call add_materialization_data(); +call remove_t1_indexes(); + +-- echo /* 1.2.1 non-indexed table access */ +call remove_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 1.2.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 1.2.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); +-- source include/subselect_mat_cost.inc +call set_all_columns_nullable(); + + +-- echo /****************************************************************************** +-- echo 2. Materialization is OFF, in-to-exists is ON, materialization is cheaper. +-- echo ******************************************************************************/ +set @@optimizer_switch='materialization=off,in_to_exists=on'; + +-- echo /* 2.1 non-indexed table access */ +call remove_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 2.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 2.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); +-- source include/subselect_mat_cost.inc +call set_all_columns_nullable(); + + +-- echo /****************************************************************************** +-- echo 3. Materialization is ON, in-to-exists is OFF, in-to-exists is cheaper. +-- echo ******************************************************************************/ +set @@optimizer_switch='materialization=on,in_to_exists=off'; +# make IN-TO-EXISTS cheaper +call delete_materialization_data(); +call make_t1_indexes(); + +-- echo /* 3.1 non-indexed table access */ +call remove_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 3.2 indexed table access, nullabale columns. */ +call make_t2_indexes(); +-- source include/subselect_mat_cost.inc + +-- echo /* 3.3 indexed table access, non-nullabale columns. */ +call set_all_columns_not_null(); +-- source include/subselect_mat_cost.inc +call set_all_columns_nullable(); + + +drop procedure make_t1_indexes; +drop procedure make_t2_indexes; +drop procedure remove_t1_indexes; +drop procedure remove_t2_indexes; +drop procedure add_materialization_data; +drop procedure delete_materialization_data; +drop procedure set_all_columns_not_null; +drop procedure set_all_columns_nullable; +drop table t1, t2, t1_1024, t2_1024; + +--echo # +--echo # LP BUG#643424 valgrind warning in choose_subquery_plan() +--echo # + +CREATE TABLE t1 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + c2 int(11) DEFAULT NULL, + PRIMARY KEY (pk), + KEY c2 (c2)); + +INSERT INTO t1 VALUES (1,NULL,2); +INSERT INTO t1 VALUES (2,7,9); +INSERT INTO t1 VALUES (9,NULL,8); + +CREATE TABLE t2 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + c2 int(11) DEFAULT NULL, + PRIMARY KEY (pk), + KEY c2 (c2)); + +INSERT INTO t2 VALUES (1,1,7); + +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off'; + +SELECT pk FROM t1 WHERE (c2, c1) IN (SELECT c2, c2 FROM t2); + +set session optimizer_switch=@save_optimizer_switch; + +drop table t1, t2; + + +--echo # +--echo # LP BUG#652727 Crash in create_ref_for_key() +--echo # + +CREATE TABLE t2 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + PRIMARY KEY (pk)); + +INSERT INTO t2 VALUES (10,7); +INSERT INTO t2 VALUES (11,1); +INSERT INTO t2 VALUES (17,NULL); + +CREATE TABLE t1 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + PRIMARY KEY (pk)); + +INSERT INTO t1 VALUES (15,1); +INSERT INTO t1 VALUES (19,NULL); + +CREATE TABLE t3 (c2 int(11) DEFAULT NULL, KEY c2 (c2)); +INSERT INTO t3 VALUES (1); + +set @save_optimizer_switch=@@optimizer_switch; +set @@optimizer_switch='materialization=on,in_to_exists=on,semijoin=off'; + +SELECT c2 +FROM t3 +WHERE (2, 6) IN (SELECT t1.c1, t1.c1 FROM t1 STRAIGHT_JOIN t2 ON t2.pk = t1.pk); + +set session optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3; + + +--echo # +--echo # LP BUG#641245 Crash in Item_equal::contains +--echo # + +CREATE TABLE t1 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + c2 int(11) DEFAULT NULL, + c3 varchar(1) DEFAULT NULL, + c4 varchar(1) DEFAULT NULL, + PRIMARY KEY (pk), + KEY c2 (c2), + KEY c3 (c3,c2)); + +INSERT INTO t1 VALUES (10,7,8,'v','v'); +INSERT INTO t1 VALUES (11,1,9,'r','r'); +INSERT INTO t1 VALUES (12,5,9,'a','a'); + +create table t1a like t1; +insert into t1a select * from t1; + +create table t1b like t1; +insert into t1b select * from t1; + +CREATE TABLE t2 ( + pk int(11) NOT NULL AUTO_INCREMENT, + c1 int(11) DEFAULT NULL, + c2 int(11) DEFAULT NULL, + c3 varchar(1) DEFAULT NULL, + c4 varchar(1) DEFAULT NULL, + PRIMARY KEY (pk), + KEY c2 (c2), + KEY c3 (c3,c2)); + +INSERT INTO t2 VALUES (1,NULL,2,'w','w'); +INSERT INTO t2 VALUES (2,7,9,'m','m'); + +set @@optimizer_switch='materialization=off,in_to_exists=on,semijoin=off'; + +let $query= +SELECT pk +FROM t1 +WHERE c1 IN + (SELECT t1a.c1 + FROM (t1b JOIN t2 ON t2.c3 = t1b.c4) LEFT JOIN + t1a ON (t1a.c2 = t1b.pk AND 2) + WHERE t1.pk) ; +eval EXPLAIN EXTENDED $query; +eval $query; + +DROP TABLE t1, t1a, t1b, t2; diff --git a/sql/filesort.cc b/sql/filesort.cc index 8f03ee26691..65e4116479c 100644 --- a/sql/filesort.cc +++ b/sql/filesort.cc @@ -612,10 +612,34 @@ static ha_rows find_all_keys(SORTPARAM *param, SQL_SELECT *select, } DBUG_RETURN(HA_POS_ERROR); /* purecov: inspected */ } + + bool write_record= false; if (error == 0) + { param->examined_rows++; - - if (error == 0 && (!select || select->skip_record(thd) > 0)) + if (select && select->cond) + { + /* + If the condition 'select->cond' contains a subquery, restore the + original read/write sets of the table 'sort_form' because when + SQL_SELECT::skip_record evaluates this condition. it may include a + correlated subquery predicate, such that some field in the subquery + refers to 'sort_form'. + */ + if (select->cond->with_subselect) + sort_form->column_bitmaps_set(save_read_set, save_write_set, + save_vcol_set); + write_record= (select->skip_record(thd) > 0); + if (select->cond->with_subselect) + sort_form->column_bitmaps_set(&sort_form->tmp_set, + &sort_form->tmp_set, + &sort_form->tmp_set); + } + else + write_record= true; + } + + if (write_record) { if (idx == param->keys) { @@ -628,7 +652,7 @@ static ha_rows find_all_keys(SORTPARAM *param, SQL_SELECT *select, } else file->unlock_row(); - + /* It does not make sense to read more keys in case of a fatal error */ if (thd->is_error()) break; diff --git a/sql/item.cc b/sql/item.cc index 310e6994c7d..188200bd7bd 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -387,6 +387,8 @@ Item::Item(): decimals= 0; max_length= 0; with_subselect= 0; cmp_context= IMPOSSIBLE_RESULT; + /* Initially this item is not attached to any JOIN_TAB. */ + join_tab_idx= MAX_TABLES; /* Put item in free list so that we can free all items at end */ THD *thd= current_thd; @@ -415,6 +417,7 @@ Item::Item(): tables. */ Item::Item(THD *thd, Item *item): + join_tab_idx(item->join_tab_idx), is_expensive_cache(-1), rsize(0), str_value(item->str_value), @@ -472,6 +475,7 @@ void Item::cleanup() DBUG_ENTER("Item::cleanup"); fixed=0; marker= 0; + join_tab_idx= MAX_TABLES; if (orig_name) name= orig_name; DBUG_VOID_RETURN; diff --git a/sql/item.h b/sql/item.h index d57155da9b1..f78f25bb9d2 100644 --- a/sql/item.h +++ b/sql/item.h @@ -491,6 +491,17 @@ typedef void (*Cond_traverser) (const Item *item, void *arg); class Item { Item(const Item &); /* Prevent use of these */ void operator=(Item &); + /** + The index in the JOIN::join_tab array of the JOIN_TAB this Item is attached + to. Items are attached (or 'pushed') to JOIN_TABs during optimization by the + make_cond_for_table procedure. During query execution, this item is + evaluated when the join loop reaches the corresponding JOIN_TAB. + + If the value of join_tab_idx >= MAX_TABLES, this means that there is no + corresponding JOIN_TAB. + */ + uint join_tab_idx; + public: static void *operator new(size_t size) throw () { return sql_alloc(size); } @@ -950,6 +961,8 @@ public: virtual bool register_field_in_read_map(uchar *arg) { return 0; } virtual bool enumerate_field_refs_processor(uchar *arg) { return 0; } virtual bool mark_as_eliminated_processor(uchar *arg) { return 0; } + virtual bool eliminate_subselect_processor(uchar *arg) { return 0; } + virtual bool set_fake_select_as_master_processor(uchar *arg) { return 0; } /* To call bool function for all arguments */ struct bool_func_call_args @@ -1179,6 +1192,16 @@ public: Item* set_expr_cache(THD *thd, List<Item*> &depends_on); virtual Item *get_cached_item() { return NULL; } + /** + Set the join tab index to the minimal (left-most) JOIN_TAB to which this + Item is attached. + */ + virtual void set_join_tab_idx(uint join_tab_idx_arg) + { + if (join_tab_idx_arg < join_tab_idx) + join_tab_idx= join_tab_idx_arg; + } + virtual uint get_join_tab_idx() { return join_tab_idx; } }; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 0b89adb75e8..e4a1eb1473e 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -2065,6 +2065,18 @@ Item *Item_in_optimizer::transform(Item_transformer transformer, uchar *argument } +bool Item_in_optimizer::is_expensive_processor(uchar *arg) +{ + return args[1]->is_expensive_processor(arg); +} + + +bool Item_in_optimizer::is_expensive() +{ + return args[1]->is_expensive(); +} + + longlong Item_func_eq::val_int() { DBUG_ASSERT(fixed == 1); @@ -4730,12 +4742,6 @@ Item *and_expressions(Item *a, Item *b, Item **org_item) longlong Item_func_isnull::val_int() { DBUG_ASSERT(fixed == 1); - /* - Handle optimization if the argument can't be null - This has to be here because of the test in update_used_tables(). - */ - if (!used_tables_cache && !with_subselect) - return cached_value; return args[0]->is_null() ? 1: 0; } @@ -4743,12 +4749,6 @@ longlong Item_is_not_null_test::val_int() { DBUG_ASSERT(fixed == 1); DBUG_ENTER("Item_is_not_null_test::val_int"); - if (!used_tables_cache && !with_subselect) - { - owner->was_null|= (!cached_value); - DBUG_PRINT("info", ("cached: %ld", (long) cached_value)); - DBUG_RETURN(cached_value); - } if (args[0]->is_null()) { DBUG_PRINT("info", ("null")); @@ -4765,19 +4765,9 @@ longlong Item_is_not_null_test::val_int() void Item_is_not_null_test::update_used_tables() { if (!args[0]->maybe_null) - { used_tables_cache= 0; /* is always true */ - cached_value= (longlong) 1; - } else - { args[0]->update_used_tables(); - if (!(used_tables_cache=args[0]->used_tables()) && !with_subselect) - { - /* Remember if the value is always NULL or never NULL */ - cached_value= (longlong) !args[0]->is_null(); - } - } } @@ -5453,7 +5443,7 @@ Item *Item_func_nop_all::neg_transformer(THD *thd) /* "NOT (e $cmp$ ANY (SELECT ...)) -> e $rev_cmp$" ALL (SELECT ...) */ Item_func_not_all *new_item= new Item_func_not_all(args[0]); Item_allany_subselect *allany= (Item_allany_subselect*)args[0]; - allany->func= allany->func_creator(FALSE); + allany->create_comp_func(FALSE); allany->all= !allany->all; allany->upper_item= new_item; return new_item; @@ -5465,7 +5455,7 @@ Item *Item_func_not_all::neg_transformer(THD *thd) Item_func_nop_all *new_item= new Item_func_nop_all(args[0]); Item_allany_subselect *allany= (Item_allany_subselect*)args[0]; allany->all= !allany->all; - allany->func= allany->func_creator(TRUE); + allany->create_comp_func(TRUE); allany->upper_item= new_item; return new_item; } @@ -5748,6 +5738,9 @@ longlong Item_equal::val_int() Item_field *item_field; if (cond_false) return 0; + /* If there is a single constant and no fields, the equality is TRUE. */ + if (const_item && !fields.elements) + return 1; List_iterator_fast<Item_field> it(fields); Item *item= const_item ? const_item : it++; if ((null_value= item->is_null())) @@ -5768,6 +5761,15 @@ longlong Item_equal::val_int() void Item_equal::fix_length_and_dec() { Item *item= get_first(NULL); + if (!item) + { + /* + If there are no fields, there must be at least a constant, in which + case Item_equal::val_int evaluates to TRUE. + */ + DBUG_ASSERT(const_item); + return; + } eval_item= cmp_item::get_comparator(item->result_type(), item->collation.collation); } diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index 8a62f69de1f..0f197cc6880 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -266,6 +266,10 @@ public: void keep_top_level_cache(); Item *transform(Item_transformer transformer, uchar *arg); virtual Item *expr_cache_insert_transformer(uchar *thd_arg); + bool is_expensive_processor(uchar *arg); + bool is_expensive(); + void set_join_tab_idx(uint join_tab_idx_arg) + { args[1]->set_join_tab_idx(join_tab_idx_arg); } }; class Comp_creator @@ -1303,8 +1307,6 @@ public: class Item_func_isnull :public Item_bool_func { -protected: - longlong cached_value; public: Item_func_isnull(Item *a) :Item_bool_func(a) {} longlong val_int(); @@ -1322,18 +1324,9 @@ public: { used_tables_cache= 0; /* is always false */ const_item_cache= 1; - cached_value= (longlong) 0; } else - { args[0]->update_used_tables(); - if ((const_item_cache= !(used_tables_cache= args[0]->used_tables()) && - !with_subselect)) - { - /* Remember if the value is always NULL or never NULL */ - cached_value= (longlong) args[0]->is_null(); - } - } } table_map not_null_tables() const { return 0; } optimize_type select_optimize() const { return OPTIMIZE_NULL; } diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index ff318fa5d73..62042380a7e 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -36,8 +36,8 @@ Item_subselect::Item_subselect(): Item_result_field(), value_assigned(0), thd(0), substitution(0), expr_cache(0), engine(0), old_engine(0), used_tables_cache(0), have_to_be_excluded(0), const_item_cache(1), inside_first_fix_fields(0), - done_first_fix_fields(FALSE), eliminated(FALSE), engine_changed(0), - changed(0), is_correlated(FALSE) + done_first_fix_fields(FALSE), forced_const(FALSE), eliminated(FALSE), + engine_changed(0), changed(0), is_correlated(FALSE) { with_subselect= 1; reset(); @@ -123,6 +123,7 @@ void Item_subselect::cleanup() reset(); value_assigned= 0; expr_cache= 0; + forced_const= FALSE; DBUG_VOID_RETURN; } @@ -160,7 +161,9 @@ void Item_in_subselect::cleanup() left_expr_cache= NULL; } first_execution= TRUE; - is_constant= FALSE; + if (in_strategy & SUBS_MATERIALIZATION) + in_strategy= 0; + pushed_cond_guards= NULL; Item_subselect::cleanup(); DBUG_VOID_RETURN; } @@ -168,13 +171,14 @@ void Item_in_subselect::cleanup() Item_subselect::~Item_subselect() { delete engine; + engine= NULL; } -Item_subselect::trans_res +bool Item_subselect::select_transformer(JOIN *join) { DBUG_ENTER("Item_subselect::select_transformer"); - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); } @@ -209,11 +213,7 @@ bool Item_subselect::fix_fields(THD *thd_param, Item **ref) { // all transformation is done (used by prepared statements) changed= 1; - inside_first_fix_fields= FALSE; - - - // all transformation is done (used by prepared statements) - changed= 1; + inside_first_fix_fields= FALSE; /* Substitute the current item with an Item_in_optimizer that was @@ -223,11 +223,14 @@ bool Item_subselect::fix_fields(THD *thd_param, Item **ref) */ if (substitution) { - // did we changed top item of WHERE condition + /* + If the top item of the WHERE/HAVING condition changed, + set correct WHERE/HAVING for PS. + */ if (unit->outer_select()->where == (*ref)) - unit->outer_select()->where= substitution; // correct WHERE for PS + thd->change_item_tree(&(unit->outer_select()->where), substitution); else if (unit->outer_select()->having == (*ref)) - unit->outer_select()->having= substitution; // correct HAVING for PS + thd->change_item_tree(&(unit->outer_select()->having), substitution); (*ref)= substitution; substitution->name= name; @@ -287,6 +290,73 @@ bool Item_subselect::mark_as_eliminated_processor(uchar *arg) } +/** + Remove a subselect item from its unit so that the unit no longer + represents a subquery. + + @param arg unused parameter + + @return + FALSE to force the evaluation of the processor for the subsequent items. +*/ + +bool Item_subselect::eliminate_subselect_processor(uchar *arg) +{ + unit->item= NULL; + unit->exclude_from_tree(); + eliminated= TRUE; + return FALSE; +} + + +/** + Adjust the master select of the subquery to be the fake_select which + represents the whole UNION right above the subquery, instead of the + last query of the UNION. + + @param arg pointer to the fake select + + @return + FALSE to force the evaluation of the processor for the subsequent items. +*/ + +bool Item_subselect::set_fake_select_as_master_processor(uchar *arg) +{ + SELECT_LEX *fake_select= (SELECT_LEX*) arg; + /* + Move the st_select_lex_unit of a subquery from a global ORDER BY clause to + become a direct child of the fake_select of a UNION. In this way the + ORDER BY is applied to the temporary table that contains the result of the + whole UNION, and all columns in the subquery are resolved against this table. + + Apply the transformation only for immediate child subqueries of a + UNION query. + */ + if (unit->outer_select()->master_unit()->fake_select_lex == fake_select) + { + /* + Set the master of the subquery to be the fake select (i.e. the whole UNION), + instead of the last query in the UNION. + TODO: + This is a hack, instead we should call: unit->include_down(fake_select); + However, this call results in an infinite loop where + some_select_lex->master == some_select_lex. + */ + unit->set_master(fake_select); + /* Adjust the name resolution context hierarchy accordingly. */ + for (SELECT_LEX *sl= unit->first_select(); sl; sl= sl->next_select()) + sl->context.outer_context= &(fake_select->context); + /* + Undo Item_subselect::eliminate_subselect_processor because at that phase + we don't know yet that the ORDER clause will be moved to the fake select. + */ + unit->item= this; + eliminated= FALSE; + } + return FALSE; +} + + bool Item_subselect::mark_as_dependent(THD *thd, st_select_lex *select, Item *item) { @@ -561,7 +631,7 @@ bool Item_in_subselect::exec() - on a cost-based basis, that takes into account the cost of a cache lookup, the cache hit rate, and the savings per cache hit. */ - if (!left_expr_cache && exec_method == MATERIALIZATION) + if (!left_expr_cache && (in_strategy & SUBS_MATERIALIZATION)) init_left_expr_cache(); /* @@ -614,12 +684,15 @@ Item *Item_subselect::get_tmp_table_item(THD *thd_arg) void Item_subselect::update_used_tables() { - recalc_used_tables(parent_select, FALSE); - if (!engine->uncacheable()) + if (!forced_const) { - // did all used tables become static? - if (!(used_tables_cache & ~engine->upper_select_const_tables())) - const_item_cache= 1; + recalc_used_tables(parent_select, FALSE); + if (!engine->uncacheable()) + { + // did all used tables become static? + if (!(used_tables_cache & ~engine->upper_select_const_tables())) + const_item_cache= 1; + } } } @@ -685,7 +758,7 @@ Item_maxmin_subselect::Item_maxmin_subselect(THD *thd_param, of Items belonged to subquery, which will be not repeated */ used_tables_cache= parent->get_used_tables_cache(); - const_item_cache= parent->get_const_item_cache(); + const_item_cache= parent->const_item(); /* this subquery always creates during preparation, so we can assign @@ -723,8 +796,7 @@ void Item_maxmin_subselect::print(String *str, enum_query_type query_type) void Item_singlerow_subselect::reset() { - eliminated= FALSE; - null_value= TRUE; + Item_subselect::reset(); if (value) value->null_value= TRUE; } @@ -739,13 +811,17 @@ void Item_singlerow_subselect::reset() - switch off this optimization for prepare statement, because we do not rollback this changes. Make rollback for it, or special name resolving mode in 5.0. + + @param join Join object of the subquery (i.e. 'child' join). + + @retval false The subquery was transformed */ -Item_subselect::trans_res +bool Item_singlerow_subselect::select_transformer(JOIN *join) { DBUG_ENTER("Item_singlerow_subselect::select_transformer"); if (changed) - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); SELECT_LEX *select_lex= join->select_lex; Query_arena *arena= thd->stmt_arena; @@ -772,7 +848,6 @@ Item_singlerow_subselect::select_transformer(JOIN *join) !arena->is_stmt_prepare_or_first_sp_execute() ) { - have_to_be_excluded= 1; if (thd->lex->describe) { @@ -788,9 +863,8 @@ Item_singlerow_subselect::select_transformer(JOIN *join) */ substitution->walk(&Item::remove_dependence_processor, 0, (uchar *) select_lex->outer_select()); - DBUG_RETURN(RES_REDUCE); } - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); } @@ -1021,11 +1095,11 @@ bool Item_in_subselect::test_limit(st_select_lex_unit *unit_arg) Item_in_subselect::Item_in_subselect(Item * left_exp, st_select_lex *select_lex): Item_exists_subselect(), left_expr_cache(0), first_execution(TRUE), - is_constant(FALSE), optimizer(0), pushed_cond_guards(NULL), - exec_method(NOT_TRANSFORMED), upper_item(0) + optimizer(0), pushed_cond_guards(NULL), in_strategy(0), upper_item(0) { DBUG_ENTER("Item_in_subselect::Item_in_subselect"); left_expr= left_exp; + func= &eq_creator; init(select_lex, new select_exists_subselect(this)); max_columns= UINT_MAX; maybe_null= 1; @@ -1252,7 +1326,7 @@ bool Item_in_subselect::val_bool() { DBUG_ASSERT(fixed == 1); null_value= was_null= FALSE; - if (is_constant) + if (forced_const) return value; if (exec()) { @@ -1285,59 +1359,37 @@ my_decimal *Item_in_subselect::val_decimal(my_decimal *decimal_value) } -/* - Rewrite a single-column IN/ALL/ANY subselect - - SYNOPSIS - Item_in_subselect::single_value_transformer() - join Join object of the subquery (i.e. 'child' join). - func Subquery comparison creator - - DESCRIPTION - Rewrite a single-column subquery using rule-based approach. The subquery - - oe $cmp$ (SELECT ie FROM ... WHERE subq_where ... HAVING subq_having) - - First, try to convert the subquery to scalar-result subquery in one of - the forms: - - - oe $cmp$ (SELECT MAX(...) ) // handled by Item_singlerow_subselect - - oe $cmp$ <max>(SELECT ...) // handled by Item_maxmin_subselect - - If that fails, the subquery will be handled with class Item_in_optimizer, - Inject the predicates into subquery, i.e. convert it to: - - - If the subquery has aggregates, GROUP BY, or HAVING, convert to - - SELECT ie FROM ... HAVING subq_having AND - trigcond(oe $cmp$ ref_or_null_helper<ie>) - - the addition is wrapped into trigger only when we want to distinguish - between NULL and FALSE results. +/** + Rewrite a single-column IN/ALL/ANY subselect. - - Otherwise (no aggregates/GROUP BY/HAVING) convert it to one of the - following: + @param join Join object of the subquery (i.e. 'child' join). - = If we don't need to distinguish between NULL and FALSE subquery: - - SELECT 1 FROM ... WHERE (oe $cmp$ ie) AND subq_where + @details + Rewrite a single-column subquery using rule-based approach. Given the subquery - = If we need to distinguish between those: + oe $cmp$ (SELECT ie FROM ... WHERE subq_where ... HAVING subq_having) - SELECT 1 FROM ... - WHERE subq_where AND trigcond((oe $cmp$ ie) OR (ie IS NULL)) - HAVING trigcond(<is_not_null_test>(ie)) + First, try to convert the subquery to a scalar-result subquery in one of + the forms: + + - oe $cmp$ (SELECT MAX(...) ) // handled by Item_singlerow_subselect + - oe $cmp$ <max>(SELECT ...) // handled by Item_maxmin_subselect - RETURN - RES_OK Either subquery was transformed, or appopriate - predicates where injected into it. - RES_REDUCE The subquery was reduced to non-subquery - RES_ERROR Error + If that fails, check if the subquery is a single select without tables, + and substitute the subquery predicate with "oe $cmp$ ie". + + If that fails, the subquery predicate is wrapped into an Item_in_optimizer. + Later the query optimization phase chooses whether the subquery under the + Item_in_optimizer will be further transformed into an equivalent correlated + EXISTS by injecting additional predicates, or will be executed via subquery + materialization in its unmodified form. + + @retval false The subquery was transformed + @retval true Error */ -Item_subselect::trans_res -Item_in_subselect::single_value_transformer(JOIN *join, - Comp_creator *func) +bool +Item_in_subselect::single_value_transformer(JOIN *join) { SELECT_LEX *select_lex= join->select_lex; DBUG_ENTER("Item_in_subselect::single_value_transformer"); @@ -1350,7 +1402,7 @@ Item_in_subselect::single_value_transformer(JOIN *join, if (select_lex->item_list.elements > 1) { my_error(ER_OPERAND_COLUMNS, MYF(0), 1); - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } /* @@ -1369,8 +1421,8 @@ Item_in_subselect::single_value_transformer(JOIN *join, { if (substitution) { - // It is second (third, ...) SELECT of UNION => All is done - DBUG_RETURN(RES_OK); + /* It is second (third, ...) SELECT of UNION => All is done */ + DBUG_RETURN(false); } Item *subs; @@ -1415,7 +1467,7 @@ Item_in_subselect::single_value_transformer(JOIN *join, we do not check item->fixed */ if (item->fix_fields(thd, 0)) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); thd->lex->allow_sum_func= save_allow_sum_func; /* we added aggregate function => we have to change statistic */ count_field_types(select_lex, &join->tmp_table_param, join->all_fields, @@ -1432,9 +1484,39 @@ Item_in_subselect::single_value_transformer(JOIN *join, } /* fix fields is already called for left expression */ substitution= func->create(left_expr, subs); - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); + } + + Item* join_having= join->having ? join->having : join->tmp_having; + if (!(join_having || select_lex->with_sum_func || + select_lex->group_list.elements) && + select_lex->table_list.elements == 0 && + !select_lex->master_unit()->is_union()) + { + Item *where_item= (Item*) select_lex->item_list.head(); + /* + it is single select without tables => possible optimization + remove the dependence mark since the item is moved to upper + select and is not outer anymore. + */ + where_item->walk(&Item::remove_dependence_processor, 0, + (uchar *) select_lex->outer_select()); + substitution= func->create(left_expr, where_item); + have_to_be_excluded= 1; + if (thd->lex->describe) + { + char warn_buff[MYSQL_ERRMSG_SIZE]; + sprintf(warn_buff, ER(ER_SELECT_REDUCED), select_lex->select_number); + push_warning(thd, MYSQL_ERROR::WARN_LEVEL_NOTE, + ER_SELECT_REDUCED, warn_buff); + } + DBUG_RETURN(false); } + /* + Wrap the current IN predicate in an Item_in_optimizer. The actual + substitution in the Item tree takes place in Item_subselect::fix_fields. + */ if (!substitution) { /* We're invoked for the 1st (or the only) SELECT in the subquery UNION */ @@ -1448,7 +1530,7 @@ Item_in_subselect::single_value_transformer(JOIN *join, if (!optimizer || optimizer->fix_left(thd, 0)) { thd->lex->current_select= current; - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } thd->lex->current_select= current; @@ -1465,33 +1547,37 @@ Item_in_subselect::single_value_transformer(JOIN *join, (char *)in_left_expr_name); master_unit->uncacheable|= UNCACHEABLE_DEPENDENT; - //psergey: placed then removed: select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; + // TODO: do we need to set both? + // select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; } - if (!abort_on_null && left_expr->maybe_null && !pushed_cond_guards) - { - if (!(pushed_cond_guards= (bool*)join->thd->alloc(sizeof(bool)))) - DBUG_RETURN(RES_ERROR); - pushed_cond_guards[0]= TRUE; - } + DBUG_RETURN(false); +} - /* - If this IN predicate can be computed via materialization, do not - perform the IN -> EXISTS transformation. - */ - if (exec_method == MATERIALIZATION) - DBUG_RETURN(RES_OK); - /* Perform the IN=>EXISTS transformation. */ - DBUG_RETURN(single_value_in_to_exists_transformer(join, func)); +bool Item_in_subselect::fix_having(Item *having, SELECT_LEX *select_lex) +{ + bool fix_res= 0; + if (!having->fixed) + { + select_lex->having_fix_field= 1; + fix_res= having->fix_fields(thd, 0); + select_lex->having_fix_field= 0; + } + return fix_res; } /** - Transofrm an IN predicate into EXISTS via predicate injection. + Create the predicates needed to transform a single-column IN/ALL/ANY + subselect into a correlated EXISTS via predicate injection. - @details The transformation injects additional predicates into the subquery - (and makes the subquery correlated) as follows. + @param join[in] Join object of the subquery (i.e. 'child' join). + @param where_item[out] the in-to-exists addition to the where clause + @param having_item[out] the in-to-exists addition to the having clause + + @details + The correlated predicates are created as follows: - If the subquery has aggregates, GROUP BY, or HAVING, convert to @@ -1506,34 +1592,38 @@ Item_in_subselect::single_value_transformer(JOIN *join, = If we don't need to distinguish between NULL and FALSE subquery: - SELECT 1 FROM ... WHERE (oe $cmp$ ie) AND subq_where + SELECT ie FROM ... WHERE subq_where AND (oe $cmp$ ie) = If we need to distinguish between those: - SELECT 1 FROM ... + SELECT ie FROM ... WHERE subq_where AND trigcond((oe $cmp$ ie) OR (ie IS NULL)) HAVING trigcond(<is_not_null_test>(ie)) - @param join Join object of the subquery (i.e. 'child' join). - @param func Subquery comparison creator - - @retval RES_OK Either subquery was transformed, or appopriate - predicates where injected into it. - @retval RES_REDUCE The subquery was reduced to non-subquery - @retval RES_ERROR Error + @retval false If the new conditions were created successfully + @retval true Error */ -Item_subselect::trans_res -Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creator *func) +bool +Item_in_subselect::create_single_in_to_exists_cond(JOIN * join, + Item **where_item, + Item **having_item) { SELECT_LEX *select_lex= join->select_lex; - DBUG_ENTER("Item_in_subselect::single_value_in_to_exists_transformer"); + /* + The non-transformed HAVING clause of 'join' may be stored in two ways + during JOIN::optimize: this->tmp_having= this->having; this->having= 0; + */ + Item* join_having= join->having ? join->having : join->tmp_having; + + DBUG_ENTER("Item_in_subselect::create_single_in_to_exists_cond"); + + *where_item= NULL; + *having_item= NULL; - select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; - if (join->having || select_lex->with_sum_func || + if (join_having || select_lex->with_sum_func || select_lex->group_list.elements) { - bool tmp; Item *item= func->create(expr, new Item_ref_null_helper(&select_lex->context, this, @@ -1549,24 +1639,12 @@ Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creat */ item= new Item_func_trig_cond(item, get_cond_guard(0)); } - - /* - AND and comparison functions can't be changed during fix_fields() - we can assign select_lex->having here, and pass 0 as last - argument (reference) to fix_fields() - */ - select_lex->having= join->having= and_items(join->having, item); - if (join->having == item) - item->name= (char*)in_having_cond; - select_lex->having_fix_field= 1; - /* - we do not check join->having->fixed, because Item_and (from and_items) - or comparison function (from func->create) can't be fixed after creation - */ - tmp= join->having->fix_fields(thd, 0); - select_lex->having_fix_field= 0; - if (tmp) - DBUG_RETURN(RES_ERROR); + + if (!join_having) + item->name= (char*) in_having_cond; + if (fix_having(item, select_lex)) + DBUG_RETURN(true); + *having_item= item; } else { @@ -1574,13 +1652,8 @@ Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creat if (select_lex->table_list.elements) { - bool tmp; - Item *having= item, *orig_item= item; - select_lex->item_list.empty(); - select_lex->item_list.push_back(new Item_int("Not_used", - (longlong) 1, - MY_INT64_NUM_DECIMAL_DIGITS)); - select_lex->ref_pointer_array[0]= select_lex->item_list.head(); + Item *having= item; + Item *orig_item= item; item= func->create(expr, item); if (!abort_on_null && orig_item->maybe_null) @@ -1590,25 +1663,13 @@ Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creat { if (!(having= new Item_func_trig_cond(having, get_cond_guard(0)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } - /* - Item_is_not_null_test can't be changed during fix_fields() - we can assign select_lex->having here, and pass 0 as last - argument (reference) to fix_fields() - */ - having->name= (char*)in_having_cond; - select_lex->having= join->having= having; - select_lex->having_fix_field= 1; - /* - we do not check join->having->fixed, because Item_and (from - and_items) or comparison function (from func->create) can't be - fixed after creation - */ - tmp= join->having->fix_fields(thd, 0); - select_lex->having_fix_field= 0; - if (tmp) - DBUG_RETURN(RES_ERROR); + having->name= (char*) in_having_cond; + if (fix_having(having, select_lex)) + DBUG_RETURN(true); + *having_item= having; + item= new Item_cond_or(item, new Item_func_isnull(orig_item)); } @@ -1619,39 +1680,23 @@ Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creat if (!abort_on_null && left_expr->maybe_null) { if (!(item= new Item_func_trig_cond(item, get_cond_guard(0)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } + /* TODO: figure out why the following is done here in single_value_transformer but there is no corresponding action in row_value_transformer? */ - item->name= (char *)in_additional_cond; - - /* - AND can't be changed during fix_fields() - we can assign select_lex->having here, and pass 0 as last - argument (reference) to fix_fields() - */ - select_lex->where= join->conds= and_items(join->conds, item); - select_lex->where->top_level_item(); - /* - we do not check join->conds->fixed, because Item_and can't be fixed - after creation - */ - if (join->conds->fix_fields(thd, 0)) - DBUG_RETURN(RES_ERROR); + item->name= (char *) in_additional_cond; + if (!item->fixed && item->fix_fields(thd, 0)) + DBUG_RETURN(true); + *where_item= item; } else { - bool tmp; if (select_lex->master_unit()->is_union()) { - /* - comparison functions can't be changed during fix_fields() - we can assign select_lex->having here, and pass 0 as last - argument (reference) to fix_fields() - */ Item *new_having= func->create(expr, new Item_ref_null_helper(&select_lex->context, this, @@ -1662,49 +1707,40 @@ Item_in_subselect::single_value_in_to_exists_transformer(JOIN * join, Comp_creat { if (!(new_having= new Item_func_trig_cond(new_having, get_cond_guard(0)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } - new_having->name= (char*)in_having_cond; - select_lex->having= join->having= new_having; - select_lex->having_fix_field= 1; - - /* - we do not check join->having->fixed, because comparison function - (from func->create) can't be fixed after creation - */ - tmp= join->having->fix_fields(thd, 0); - select_lex->having_fix_field= 0; - if (tmp) - DBUG_RETURN(RES_ERROR); + + new_having->name= (char*) in_having_cond; + if (fix_having(new_having, select_lex)) + DBUG_RETURN(true); + *having_item= new_having; } else - { - // it is single select without tables => possible optimization - // remove the dependence mark since the item is moved to upper - // select and is not outer anymore. - item->walk(&Item::remove_dependence_processor, 0, - (uchar *) select_lex->outer_select()); - item= func->create(left_expr, item); - // fix_field of item will be done in time of substituting - substitution= item; - have_to_be_excluded= 1; - if (thd->lex->describe) - { - char warn_buff[MYSQL_ERRMSG_SIZE]; - sprintf(warn_buff, ER(ER_SELECT_REDUCED), select_lex->select_number); - push_warning(thd, MYSQL_ERROR::WARN_LEVEL_NOTE, - ER_SELECT_REDUCED, warn_buff); - } - DBUG_RETURN(RES_REDUCE); - } + DBUG_ASSERT(FALSE); } } - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); } -Item_subselect::trans_res +/** + Wrap a multi-column IN/ALL/ANY subselect into an Item_in_optimizer. + + @param join Join object of the subquery (i.e. 'child' join). + + @details + The subquery predicate is wrapped into an Item_in_optimizer. Later the query + optimization phase chooses whether the subquery under the Item_in_optimizer + will be further transformed into an equivalent correlated EXISTS by injecting + additional predicates, or will be executed via subquery materialization in its + unmodified form. + + @retval false The subquery was transformed + @retval true Error +*/ + +bool Item_in_subselect::row_value_transformer(JOIN *join) { SELECT_LEX *select_lex= join->select_lex; @@ -1716,7 +1752,7 @@ Item_in_subselect::row_value_transformer(JOIN *join) if (select_lex->item_list.elements != cols_num) { my_error(ER_OPERAND_COLUMNS, MYF(0), cols_num); - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } /* @@ -1735,7 +1771,7 @@ Item_in_subselect::row_value_transformer(JOIN *join) if (!optimizer || optimizer->fix_left(thd, 0)) { thd->lex->current_select= current; - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } // we will refer to upper level cache array => we have to save it in PS @@ -1743,86 +1779,99 @@ Item_in_subselect::row_value_transformer(JOIN *join) thd->lex->current_select= current; master_unit->uncacheable|= UNCACHEABLE_DEPENDENT; - - if (!abort_on_null && left_expr->maybe_null && !pushed_cond_guards) - { - if (!(pushed_cond_guards= (bool*)join->thd->alloc(sizeof(bool) * - left_expr->cols()))) - DBUG_RETURN(RES_ERROR); - for (uint i= 0; i < cols_num; i++) - pushed_cond_guards[i]= TRUE; - } + // TODO: do we need to set both? + //select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; } - /* - If this IN predicate can be computed via materialization, do not - perform the IN -> EXISTS transformation. - */ - if (exec_method == MATERIALIZATION) - DBUG_RETURN(RES_OK); - - /* Perform the IN=>EXISTS transformation. */ - DBUG_RETURN(row_value_in_to_exists_transformer(join)); + DBUG_RETURN(false); } /** - Tranform a (possibly non-correlated) IN subquery into a correlated EXISTS. + Create the predicates needed to transform a multi-column IN/ALL/ANY + subselect into a correlated EXISTS via predicate injection. - @todo - The IF-ELSE below can be refactored so that there is no duplication of the - statements that create the new conditions. For this we have to invert the IF - and the FOR statements as this: - for (each left operand) - create the equi-join condition - if (is_having_used || !abort_on_null) - create the "is null" and is_not_null_test items - if (is_having_used) - add the equi-join and the null tests to HAVING - else - add the equi-join and the "is null" to WHERE - add the is_not_null_test to HAVING + @details + The correlated predicates are created as follows: + + - If the subquery has aggregates, GROUP BY, or HAVING, convert to + + (l1, l2, l3) IN (SELECT v1, v2, v3 ... HAVING having) + => + EXISTS (SELECT ... HAVING having and + (l1 = v1 or is null v1) and + (l2 = v2 or is null v2) and + (l3 = v3 or is null v3) and + is_not_null_test(v1) and + is_not_null_test(v2) and + is_not_null_test(v3)) + + where is_not_null_test used to register nulls in case if we have + not found matching to return correct NULL value. + + - Otherwise (no aggregates/GROUP BY/HAVING) convert the subquery as follows: + + (l1, l2, l3) IN (SELECT v1, v2, v3 ... WHERE where) + => + EXISTS (SELECT ... WHERE where and + (l1 = v1 or is null v1) and + (l2 = v2 or is null v2) and + (l3 = v3 or is null v3) + HAVING is_not_null_test(v1) and + is_not_null_test(v2) and + is_not_null_test(v3)) + where is_not_null_test registers NULLs values but reject rows. + + in case when we do not need correct NULL, we have simplier construction: + EXISTS (SELECT ... WHERE where and + (l1 = v1) and + (l2 = v2) and + (l3 = v3) + + @param join[in] Join object of the subquery (i.e. 'child' join). + @param where_item[out] the in-to-exists addition to the where clause + @param having_item[out] the in-to-exists addition to the having clause + + @retval false If the new conditions were created successfully + @retval true Error */ -Item_subselect::trans_res -Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) +bool +Item_in_subselect::create_row_in_to_exists_cond(JOIN * join, + Item **where_item, + Item **having_item) { SELECT_LEX *select_lex= join->select_lex; - Item *having_item= 0; uint cols_num= left_expr->cols(); - bool is_having_used= (join->having || select_lex->with_sum_func || + /* + The non-transformed HAVING clause of 'join' may be stored in two ways + during JOIN::optimize: this->tmp_having= this->having; this->having= 0; + */ + Item* join_having= join->having ? join->having : join->tmp_having; + bool is_having_used= (join_having || select_lex->with_sum_func || select_lex->group_list.first || !select_lex->table_list.elements); - DBUG_ENTER("Item_in_subselect::row_value_in_to_exists_transformer"); + DBUG_ENTER("Item_in_subselect::create_row_in_to_exists_cond"); + + *where_item= NULL; + *having_item= NULL; - select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; if (is_having_used) { - /* - (l1, l2, l3) IN (SELECT v1, v2, v3 ... HAVING having) => - EXISTS (SELECT ... HAVING having and - (l1 = v1 or is null v1) and - (l2 = v2 or is null v2) and - (l3 = v3 or is null v3) and - is_not_null_test(v1) and - is_not_null_test(v2) and - is_not_null_test(v3)) - where is_not_null_test used to register nulls in case if we have - not found matching to return correct NULL value - TODO: say here explicitly if the order of AND parts matters or not. - */ + /* TODO: say here explicitly if the order of AND parts matters or not. */ Item *item_having_part2= 0; for (uint i= 0; i < cols_num; i++) { DBUG_ASSERT((left_expr->fixed && + select_lex->ref_pointer_array[i]->fixed) || (select_lex->ref_pointer_array[i]->type() == REF_ITEM && ((Item_ref*)(select_lex->ref_pointer_array[i]))->ref_type() == Item_ref::OUTER_REF)); if (select_lex->ref_pointer_array[i]-> check_cols(left_expr->element_index(i)->cols())) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); Item *item_eq= new Item_func_eq(new Item_ref(&select_lex->context, @@ -1834,23 +1883,21 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) Item_ref(&select_lex->context, select_lex->ref_pointer_array + i, (char *)"<no matter>", - (char *)"<list ref>") - ); + (char *)"<list ref>")); Item *item_isnull= new Item_func_isnull(new Item_ref(&select_lex->context, select_lex->ref_pointer_array+i, (char *)"<no matter>", - (char *)"<list ref>") - ); + (char *)"<list ref>")); Item *col_item= new Item_cond_or(item_eq, item_isnull); if (!abort_on_null && left_expr->element_index(i)->maybe_null) { if (!(col_item= new Item_func_trig_cond(col_item, get_cond_guard(i)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } - having_item= and_items(having_item, col_item); - + *having_item= and_items(*having_item, col_item); + Item *item_nnull_test= new Item_is_not_null_test(this, new Item_ref(&select_lex->context, @@ -1862,34 +1909,15 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) { if (!(item_nnull_test= new Item_func_trig_cond(item_nnull_test, get_cond_guard(i)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } item_having_part2= and_items(item_having_part2, item_nnull_test); item_having_part2->top_level_item(); } - having_item= and_items(having_item, item_having_part2); - having_item->top_level_item(); + *having_item= and_items(*having_item, item_having_part2); } else { - /* - (l1, l2, l3) IN (SELECT v1, v2, v3 ... WHERE where) => - EXISTS (SELECT ... WHERE where and - (l1 = v1 or is null v1) and - (l2 = v2 or is null v2) and - (l3 = v3 or is null v3) - HAVING is_not_null_test(v1) and - is_not_null_test(v2) and - is_not_null_test(v3)) - where is_not_null_test register NULLs values but reject rows - - in case when we do not need correct NULL, we have simplier construction: - EXISTS (SELECT ... WHERE where and - (l1 = v1) and - (l2 = v2) and - (l3 = v3) - */ - Item *where_item= 0; for (uint i= 0; i < cols_num; i++) { Item *item, *item_isnull; @@ -1900,7 +1928,7 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) Item_ref::OUTER_REF)); if (select_lex->ref_pointer_array[i]-> check_cols(left_expr->element_index(i)->cols())) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); item= new Item_func_eq(new Item_direct_ref(&select_lex->context, @@ -1913,8 +1941,7 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) select_lex-> ref_pointer_array+i, (char *)"<no matter>", - (char *)"<list ref>") - ); + (char *)"<list ref>")); if (!abort_on_null) { Item *having_col_item= @@ -1932,8 +1959,7 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) select_lex-> ref_pointer_array+i, (char *)"<no matter>", - (char *)"<list ref>") - ); + (char *)"<list ref>")); item= new Item_cond_or(item, item_isnull); /* TODO: why we create the above for cases where the right part @@ -1942,85 +1968,149 @@ Item_in_subselect::row_value_in_to_exists_transformer(JOIN * join) if (left_expr->element_index(i)->maybe_null) { if (!(item= new Item_func_trig_cond(item, get_cond_guard(i)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); if (!(having_col_item= new Item_func_trig_cond(having_col_item, get_cond_guard(i)))) - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } - having_item= and_items(having_item, having_col_item); + *having_item= and_items(*having_item, having_col_item); } - where_item= and_items(where_item, item); + *where_item= and_items(*where_item, item); } - /* - AND can't be changed during fix_fields() - we can assign select_lex->where here, and pass 0 as last - argument (reference) to fix_fields() - */ - select_lex->where= join->conds= and_items(join->conds, where_item); - select_lex->where->top_level_item(); - if (join->conds->fix_fields(thd, 0)) - DBUG_RETURN(RES_ERROR); } - if (having_item) + + if (*where_item) { - bool res; - select_lex->having= join->having= and_items(join->having, having_item); - if (having_item == select_lex->having) - having_item->name= (char*)in_having_cond; - select_lex->having->top_level_item(); - /* - AND can't be changed during fix_fields() - we can assign select_lex->having here, and pass 0 as last - argument (reference) to fix_fields() - */ - select_lex->having_fix_field= 1; - res= join->having->fix_fields(thd, 0); - select_lex->having_fix_field= 0; - if (res) - { - DBUG_RETURN(RES_ERROR); - } + if (!(*where_item)->fixed && (*where_item)->fix_fields(thd, 0)) + DBUG_RETURN(true); + (*where_item)->top_level_item(); + } + + if (*having_item) + { + if (!join_having) + (*having_item)->name= (char*) in_having_cond; + if (fix_having(*having_item, select_lex)) + DBUG_RETURN(true); + (*having_item)->top_level_item(); } - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); } -Item_subselect::trans_res +bool Item_in_subselect::select_transformer(JOIN *join) { - return select_in_like_transformer(join, &eq_creator); + return select_in_like_transformer(join); } /** - Prepare IN/ALL/ANY/SOME subquery transformation and call appropriate - transformation function. + Create the predicates needed to transform an IN/ALL/ANY subselect into a + correlated EXISTS via predicate injection. + + @param join_arg Join object of the subquery. + + @retval FALSE ok + @retval TRUE error +*/ + +bool Item_in_subselect::create_in_to_exists_cond(JOIN *join_arg) +{ + bool res; + + DBUG_ASSERT(engine->engine_type() == subselect_engine::SINGLE_SELECT_ENGINE || + engine->engine_type() == subselect_engine::UNION_ENGINE); + /* + TODO: the call to init_cond_guards allocates and initializes an + array of booleans that may not be used later because we may choose + materialization. + The two calls below to create_XYZ_cond depend on this boolean array. + If the dependency is removed, the call can be moved to a later phase. + */ + init_cond_guards(); + join_arg->select_lex->uncacheable|= UNCACHEABLE_DEPENDENT; + if (left_expr->cols() == 1) + res= create_single_in_to_exists_cond(join_arg, + &(join_arg->in_to_exists_where), + &(join_arg->in_to_exists_having)); + else + res= create_row_in_to_exists_cond(join_arg, + &(join_arg->in_to_exists_where), + &(join_arg->in_to_exists_having)); + return (res); +} + + +/** + Transform an IN/ALL/ANY subselect into a correlated EXISTS via injecting + correlated in-to-exists predicates. + + @param join_arg Join object of the subquery. + + @retval FALSE ok + @retval TRUE error +*/ + +bool Item_in_subselect::inject_in_to_exists_cond(JOIN *join_arg) +{ + SELECT_LEX *select_lex= join_arg->select_lex; + Item *where_item= join_arg->in_to_exists_where; + Item *having_item= join_arg->in_to_exists_having; - To decide which transformation procedure (scalar or row) applicable here - we have to call fix_fields() for left expression to be able to call - cols() method on it. Also this method make arena management for - underlying transformation methods. + DBUG_ENTER("Item_in_subselect::inject_in_to_exists_cond"); + + if (where_item) + { + where_item= and_items(join_arg->conds, where_item); + if (!where_item->fixed && where_item->fix_fields(thd, 0)) + DBUG_RETURN(true); + // TIMOUR TODO: call optimize_cond() for the new where clause + thd->change_item_tree(&select_lex->where, where_item); + select_lex->where->top_level_item(); + join_arg->conds= select_lex->where; + } + + if (having_item) + { + Item* join_having= join_arg->having ? join_arg->having:join_arg->tmp_having; + having_item= and_items(join_having, having_item); + if (fix_having(having_item, select_lex)) + DBUG_RETURN(true); + // TIMOUR TODO: call optimize_cond() for the new having clause + thd->change_item_tree(&select_lex->having, having_item); + select_lex->having->top_level_item(); + join_arg->having= select_lex->having; + } + + DBUG_RETURN(false); +} + + +/** + Prepare IN/ALL/ANY/SOME subquery transformation and call the appropriate + transformation function. @param join JOIN object of transforming subquery - @param func creator of condition function of subquery - @retval - RES_OK OK - @retval - RES_REDUCE OK, and current subquery was reduced during - transformation - @retval - RES_ERROR Error + @notes + To decide which transformation procedure (scalar or row) applicable here + we have to call fix_fields() for the left expression to be able to call + cols() method on it. Also this method makes arena management for + underlying transformation methods. + + @retval false OK + @retval true Error */ -Item_subselect::trans_res -Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func) +bool +Item_in_subselect::select_in_like_transformer(JOIN *join) { Query_arena *arena, backup; SELECT_LEX *current= thd->lex->current_select; const char *save_where= thd->where; - Item_subselect::trans_res res= RES_ERROR; + bool trans_res= true; bool result; DBUG_ENTER("Item_in_subselect::select_in_like_transformer"); @@ -2039,7 +2129,7 @@ Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func) } if (changed) - DBUG_RETURN(RES_OK); + DBUG_RETURN(false); thd->where= "IN/ALL/ANY subquery"; @@ -2071,22 +2161,15 @@ Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func) goto err; /* - If we didn't choose an execution method up to this point, we choose - the IN=>EXISTS transformation. - */ - if (exec_method == NOT_TRANSFORMED) - exec_method= IN_TO_EXISTS; - arena= thd->activate_stmt_arena_if_needed(&backup); - - /* Both transformers call fix_fields() only for Items created inside them, and all that items do not make permanent changes in current item arena which allow to us call them with changed arena (if we do not know nature of Item, we have to call fix_fields() for it only with original arena to avoid memory leack) */ + arena= thd->activate_stmt_arena_if_needed(&backup); if (left_expr->cols() == 1) - res= single_value_transformer(join, func); + trans_res= single_value_transformer(join); else { /* we do not support row operation for ALL/ANY/SOME */ @@ -2095,21 +2178,21 @@ Item_in_subselect::select_in_like_transformer(JOIN *join, Comp_creator *func) if (arena) thd->restore_active_arena(arena, &backup); my_error(ER_OPERAND_COLUMNS, MYF(0), 1); - DBUG_RETURN(RES_ERROR); + DBUG_RETURN(true); } - res= row_value_transformer(join); + trans_res= row_value_transformer(join); } if (arena) thd->restore_active_arena(arena, &backup); err: thd->where= save_where; - DBUG_RETURN(res); + DBUG_RETURN(trans_res); } void Item_in_subselect::print(String *str, enum_query_type query_type) { - if (exec_method == IN_TO_EXISTS) + if (in_strategy & SUBS_IN_TO_EXISTS) str->append(STRING_WITH_LEN("<exists>")); else { @@ -2125,7 +2208,7 @@ bool Item_in_subselect::fix_fields(THD *thd_arg, Item **ref) uint outer_cols_num; List<Item> *inner_cols; - if (exec_method == SEMI_JOIN) + if (in_strategy & SUBS_SEMI_JOIN) return !( (*ref)= new Item_int(1)); /* @@ -2198,99 +2281,47 @@ void Item_in_subselect::update_used_tables() used_tables_cache |= left_expr->used_tables(); } + /** - Try to create an engine to compute the subselect via materialization, - and if this fails, revert to execution via the IN=>EXISTS transformation. + Try to create and initialize an engine to compute a subselect via + materialization. @details - The purpose of this method is to hide the implementation details - of this Item's execution. The method creates a new engine for - materialized execution, and initializes the engine. - - If this initialization fails - - either because it wasn't possible to create the needed temporary table - and its index, - - or because of a memory allocation error, - then we revert back to execution via the IN=>EXISTS tranformation. - - The initialization of the new engine is divided in two parts - a permanent - one that lives across prepared statements, and one that is repeated for each - execution. + The method creates a new engine for materialized execution, and initializes + the engine. The initialization may fail + - either because it wasn't possible to create the needed temporary table + and its index, + - or because of a memory allocation error, @returns @retval TRUE memory allocation error occurred @retval FALSE an execution method was chosen successfully */ -bool Item_in_subselect::setup_engine() +bool Item_in_subselect::setup_mat_engine() { - subselect_hash_sj_engine *new_engine= NULL; - bool res= FALSE; - - DBUG_ENTER("Item_in_subselect::setup_engine"); + subselect_hash_sj_engine *mat_engine= NULL; + subselect_single_select_engine *select_engine; - if (engine->engine_type() == subselect_engine::SINGLE_SELECT_ENGINE) - { - /* Create/initialize objects in permanent memory. */ - subselect_single_select_engine *old_engine; - Query_arena *arena= thd->stmt_arena, backup; + DBUG_ENTER("Item_in_subselect::setup_mat_engine"); - old_engine= (subselect_single_select_engine*) engine; - - if (arena->is_conventional()) - arena= 0; - else - thd->set_n_backup_active_arena(arena, &backup); - - if (!(new_engine= new subselect_hash_sj_engine(thd, this, - old_engine)) || - new_engine->init_permanent(unit->get_unit_column_types())) - { - Item_subselect::trans_res trans_res; - /* - If for some reason we cannot use materialization for this IN predicate, - delete all materialization-related objects, and apply the IN=>EXISTS - transformation. - */ - delete new_engine; - new_engine= NULL; - exec_method= NOT_TRANSFORMED; - if (left_expr->cols() == 1) - trans_res= single_value_in_to_exists_transformer(old_engine->join, - &eq_creator); - else - trans_res= row_value_in_to_exists_transformer(old_engine->join); - res= (trans_res != Item_subselect::RES_OK); - } - if (new_engine) - engine= new_engine; + /* + The select_engine (that executes transformed IN=>EXISTS subselects) is + pre-created at parse time, and is stored in statment memory (preserved + across PS executions). + */ + DBUG_ASSERT(engine->engine_type() == subselect_engine::SINGLE_SELECT_ENGINE); + select_engine= (subselect_single_select_engine*) engine; - if (arena) - thd->restore_active_arena(arena, &backup); - } - else - { - DBUG_ASSERT(engine->engine_type() == subselect_engine::HASH_SJ_ENGINE); - new_engine= (subselect_hash_sj_engine*) engine; - } + /* Create/initialize execution objects. */ + if (!(mat_engine= new subselect_hash_sj_engine(thd, this, select_engine))) + DBUG_RETURN(TRUE); - /* Initilizations done in runtime memory, repeated for each execution. */ - if (new_engine) - { - /* - Reset the LIMIT 1 set in Item_exists_subselect::fix_length_and_dec. - TODO: - Currently we set the subquery LIMIT to infinity, and this is correct - because we forbid at parse time LIMIT inside IN subqueries (see - Item_in_subselect::test_limit). However, once we allow this, here - we should set the correct limit if given in the query. - */ - unit->global_parameters->select_limit= NULL; - if ((res= new_engine->init_runtime())) - DBUG_RETURN(res); - } + if (mat_engine->init(&select_engine->join->fields_list)) + DBUG_RETURN(TRUE); - DBUG_RETURN(res); + engine= mat_engine; + DBUG_RETURN(FALSE); } @@ -2333,39 +2364,34 @@ bool Item_in_subselect::init_left_expr_cache() } -/* - Callback to test if an IN predicate is expensive. - - @details - IN predicates are considered expensive only if they will be executed via - materialization. The return value affects the behavior of - make_cond_for_table() in such a way that it is unchanged when we use - the IN=>EXISTS transformation to compute IN. - - @retval TRUE if the predicate is expensive - @retval FALSE otherwise -*/ - -bool Item_in_subselect::is_expensive_processor(uchar *arg) +bool Item_in_subselect::init_cond_guards() { - return exec_method == MATERIALIZATION; + uint cols_num= left_expr->cols(); + if (!abort_on_null && left_expr->maybe_null && !pushed_cond_guards) + { + if (!(pushed_cond_guards= (bool*)thd->alloc(sizeof(bool) * cols_num))) + return TRUE; + for (uint i= 0; i < cols_num; i++) + pushed_cond_guards[i]= TRUE; + } + return FALSE; } -Item_subselect::trans_res +bool Item_allany_subselect::select_transformer(JOIN *join) { DBUG_ENTER("Item_allany_subselect::select_transformer"); - exec_method= IN_TO_EXISTS; + in_strategy= SUBS_IN_TO_EXISTS; if (upper_item) upper_item->show= 1; - DBUG_RETURN(select_in_like_transformer(join, func)); + DBUG_RETURN(select_in_like_transformer(join)); } void Item_allany_subselect::print(String *str, enum_query_type query_type) { - if (exec_method == IN_TO_EXISTS) + if (in_strategy & SUBS_IN_TO_EXISTS) str->append(STRING_WITH_LEN("<exists>")); else { @@ -3801,13 +3827,14 @@ bitmap_init_memroot(MY_BITMAP *map, uint n_bits, MEM_ROOT *mem_root) @retval FALSE otherwise */ -bool subselect_hash_sj_engine::init_permanent(List<Item> *tmp_columns) +bool subselect_hash_sj_engine::init(List<Item> *tmp_columns) { + select_union *result_sink; /* Options to create_tmp_table. */ ulonglong tmp_create_options= thd->options | TMP_TABLE_ALL_COLUMNS; /* | TMP_TABLE_FORCE_MYISAM; TIMOUR: force MYISAM */ - DBUG_ENTER("subselect_hash_sj_engine::init_permanent"); + DBUG_ENTER("subselect_hash_sj_engine::init"); if (bitmap_init_memroot(&non_null_key_parts, tmp_columns->elements, thd->mem_root) || @@ -3836,15 +3863,16 @@ bool subselect_hash_sj_engine::init_permanent(List<Item> *tmp_columns) DBUG_RETURN(TRUE); } */ - if (!(result= new select_materialize_with_stats)) + if (!(result_sink= new select_materialize_with_stats)) DBUG_RETURN(TRUE); - - if (((select_union*) result)->create_result_table( - thd, tmp_columns, TRUE, tmp_create_options, - "materialized subselect", TRUE)) + result_sink->get_tmp_table_param()->materialized_subquery= true; + if (result_sink->create_result_table(thd, tmp_columns, TRUE, + tmp_create_options, + "materialized subselect", TRUE)) DBUG_RETURN(TRUE); - tmp_table= ((select_union*) result)->table; + tmp_table= result_sink->table; + result= result_sink; /* If the subquery has blobs, or the total key lenght is bigger than @@ -3881,6 +3909,17 @@ bool subselect_hash_sj_engine::init_permanent(List<Item> *tmp_columns) !(lookup_engine= make_unique_engine())) DBUG_RETURN(TRUE); + /* + Repeat name resolution for 'cond' since cond is not part of any + clause of the query, and it is not 'fixed' during JOIN::prepare. + */ + if (semi_join_conds && !semi_join_conds->fixed && + semi_join_conds->fix_fields(thd, (Item**)&semi_join_conds)) + DBUG_RETURN(TRUE); + /* Let our engine reuse this query plan for materialization. */ + materialize_join= materialize_engine->join; + materialize_join->change_result(result); + DBUG_RETURN(FALSE); } @@ -3993,41 +4032,22 @@ subselect_hash_sj_engine::make_unique_engine() } -/** - Initialize members of the engine that need to be re-initilized at each - execution. +subselect_hash_sj_engine::~subselect_hash_sj_engine() +{ + delete lookup_engine; + delete result; + if (tmp_table) + free_tmp_table(thd, tmp_table); +} - @retval TRUE if a memory allocation error occurred - @retval FALSE if success -*/ -bool subselect_hash_sj_engine::init_runtime() +int subselect_hash_sj_engine::prepare() { /* Create and optimize the JOIN that will be used to materialize the subquery if not yet created. */ - materialize_engine->prepare(); - /* - Repeat name resolution for 'cond' since cond is not part of any - clause of the query, and it is not 'fixed' during JOIN::prepare. - */ - if (semi_join_conds && !semi_join_conds->fixed && - semi_join_conds->fix_fields(thd, (Item**)&semi_join_conds)) - return TRUE; - /* Let our engine reuse this query plan for materialization. */ - materialize_join= materialize_engine->join; - materialize_join->change_result(result); - return FALSE; -} - - -subselect_hash_sj_engine::~subselect_hash_sj_engine() -{ - delete lookup_engine; - delete result; - if (tmp_table) - free_tmp_table(thd, tmp_table); + return materialize_engine->prepare(); } @@ -4048,6 +4068,12 @@ void subselect_hash_sj_engine::cleanup() count_null_only_columns= 0; strategy= UNDEFINED; materialize_engine->cleanup(); + /* + Restore the original Item_in_subselect engine. This engine is created once + at parse time and stored across executions, while all other materialization + related engines are created and chosen for each execution. + */ + ((Item_in_subselect *) item)->engine= materialize_engine; if (lookup_engine_type == TABLE_SCAN_ENGINE || lookup_engine_type == ROWID_MERGE_ENGINE) { @@ -4064,6 +4090,9 @@ void subselect_hash_sj_engine::cleanup() DBUG_ASSERT(lookup_engine->engine_type() == UNIQUESUBQUERY_ENGINE); lookup_engine->cleanup(); result->cleanup(); /* Resets the temp table as well. */ + DBUG_ASSERT(tmp_table); + free_tmp_table(thd, tmp_table); + tmp_table= NULL; } @@ -4092,9 +4121,8 @@ int subselect_hash_sj_engine::exec() the subquery predicate. */ thd->lex->current_select= materialize_engine->select_lex; - if ((res= materialize_join->optimize())) - goto err; /* purecov: inspected */ - DBUG_ASSERT(!is_materialized); /* We should materialize only once. */ + /* The subquery should be optimized, and materialized only once. */ + DBUG_ASSERT(materialize_join->optimized && !is_materialized); materialize_join->exec(); if ((res= test(materialize_join->error || thd->is_fatal_error))) goto err; @@ -4118,11 +4146,10 @@ int subselect_hash_sj_engine::exec() tmp_table->file->info(HA_STATUS_VARIABLE); if (!tmp_table->file->stats.records) { - item_in->value= FALSE; /* The value of IN will not change during this execution. */ - item_in->is_constant= TRUE; + item_in->reset(); + item_in->make_const(); item_in->set_first_execution(); - /* TIMOUR: check if we need this: item_in->null_value= FALSE; */ DBUG_RETURN(FALSE); } diff --git a/sql/item_subselect.h b/sql/item_subselect.h index 8d590bc4273..54ea6986364 100644 --- a/sql/item_subselect.h +++ b/sql/item_subselect.h @@ -71,6 +71,13 @@ protected: bool inside_first_fix_fields; bool done_first_fix_fields; + /* + Set to TRUE if at optimization or execution time we determine that this + item's value is a constant. We need this member because it is not possible + to substitute 'this' with a constant item. + */ + bool forced_const; + public: /* A reference from inside subquery predicate to somewhere outside of it */ class Ref_to_outside : public Sql_alloc @@ -112,13 +119,18 @@ public: /* TRUE <=> The underlying SELECT is correlated w.r.t some ancestor select */ bool is_correlated; - enum trans_res {RES_OK, RES_REDUCE, RES_ERROR}; enum subs_type {UNKNOWN_SUBS, SINGLEROW_SUBS, EXISTS_SUBS, IN_SUBS, ALL_SUBS, ANY_SUBS}; Item_subselect(); virtual subs_type substype() { return UNKNOWN_SUBS; } + bool is_in_predicate() + { + return (substype() == Item_subselect::IN_SUBS || + substype() == Item_subselect::ALL_SUBS || + substype() == Item_subselect::ANY_SUBS); + } /* We need this method, because some compilers do not allow 'this' @@ -135,7 +147,7 @@ public: eliminated= FALSE; null_value= 1; } - virtual trans_res select_transformer(JOIN *join); + virtual bool select_transformer(JOIN *join); bool assigned() { return value_assigned; } void assigned(bool a) { value_assigned= a; } enum Type type() const; @@ -149,12 +161,21 @@ public: void fix_after_pullout(st_select_lex *new_parent, Item **ref); void recalc_used_tables(st_select_lex *new_parent, bool after_pullout); virtual bool exec(); + /* + If subquery optimization or execution determines that the subquery has + an empty result, mark the subquery predicate as a constant value. + */ + void make_const() + { + used_tables_cache= 0; + const_item_cache= 0; + forced_const= TRUE; + } virtual void fix_length_and_dec(); table_map used_tables() const; table_map not_null_tables() const { return 0; } bool const_item() const; inline table_map get_used_tables_cache() { return used_tables_cache; } - inline bool get_const_item_cache() { return const_item_cache; } Item *get_tmp_table_item(THD *thd); void update_used_tables(); virtual void print(String *str, enum_query_type query_type); @@ -172,6 +193,7 @@ public: */ bool is_evaluated() const; bool is_uncacheable() const; + bool is_expensive() { return TRUE; } /* Used by max/min subquery to initialize value presence registration @@ -181,11 +203,23 @@ public: enum_parsing_place place() { return parsing_place; } bool walk(Item_processor processor, bool walk_subquery, uchar *arg); bool mark_as_eliminated_processor(uchar *arg); + bool eliminate_subselect_processor(uchar *arg); + bool set_fake_select_as_master_processor(uchar *arg); bool enumerate_field_refs_processor(uchar *arg); bool check_vcol_func_processor(uchar *int_arg) { return trace_unsupported_by_check_vcol_func_processor("subselect"); } + /** + Callback to test if an IN predicate is expensive. + + @notes + The return value affects the behavior of make_cond_for_table(). + + @retval TRUE if the predicate is expensive + @retval FALSE otherwise + */ + bool is_expensive_processor(uchar *arg) { return TRUE; } Item *safe_charset_converter(CHARSET_INFO *tocs); /** @@ -224,7 +258,7 @@ public: subs_type substype() { return SINGLEROW_SUBS; } void reset(); - trans_res select_transformer(JOIN *join); + bool select_transformer(JOIN *join); void store(uint i, Item* item); double val_real(); longlong val_int (); @@ -313,6 +347,18 @@ public: }; +/* + Possible methods to execute an IN predicate. These are set by the optimizer + based on user-set optimizer switches, semantic analysis and cost comparison. +*/ +#define SUBS_NOT_TRANSFORMED 0 /* No execution method was chosen for this IN. */ +#define SUBS_SEMI_JOIN 1 /* IN was converted to semi-join. */ +#define SUBS_IN_TO_EXISTS 2 /* IN was converted to correlated EXISTS. */ +#define SUBS_MATERIALIZATION 4 /* Execute IN via subquery materialization. */ +/* Partial matching substrategies of MATERIALIZATION. */ +#define SUBS_PARTIAL_MATCH_ROWID_MERGE 8 +#define SUBS_PARTIAL_MATCH_TABLE_SCAN 16 + /** Representation of IN subquery predicates of the form "left_expr IN (SELECT ...)". @@ -330,8 +376,6 @@ public: class Item_in_subselect :public Item_exists_subselect { -public: - Item *left_expr; protected: /* Cache of the left operand of the subquery predicate. Allocated in the @@ -339,12 +383,6 @@ protected: */ List<Cached_item> *left_expr_cache; bool first_execution; - /* - Set to TRUE if at query execution time we determine that this item's - value is a constant during this execution. We need this member because - it is not possible to substitute 'this' with a constant item. - */ - bool is_constant; /* expr & optimizer used in subselect rewriting to store Item for @@ -354,10 +392,24 @@ protected: Item_in_optimizer *optimizer; bool was_null; bool abort_on_null; -public: /* Used to trigger on/off conditions that were pushed down to subselect */ bool *pushed_cond_guards; - + Comp_creator *func; + +protected: + bool init_cond_guards(); + bool select_in_like_transformer(JOIN *join); + bool single_value_transformer(JOIN *join); + bool row_value_transformer(JOIN * join); + bool fix_having(Item *having, st_select_lex *select_lex); + bool create_single_in_to_exists_cond(JOIN * join, + Item **where_item, + Item **having_item); + bool create_row_in_to_exists_cond(JOIN * join, + Item **where_item, + Item **having_item); +public: + Item *left_expr; /* Priority of this predicate in the convert-to-semi-join-nest process. */ int sj_convert_priority; /* @@ -388,14 +440,8 @@ public: */ bool sjm_scan_allowed; - /* The method chosen to execute the IN predicate. */ - enum enum_exec_method { - NOT_TRANSFORMED, /* No execution method was chosen for this IN. */ - SEMI_JOIN, /* IN was converted to semi-join nest and should be removed. */ - IN_TO_EXISTS, /* IN was converted to correlated EXISTS. */ - MATERIALIZATION /* IN will be executed via subquery materialization. */ - }; - enum_exec_method exec_method; + /* A bitmap of possible execution strategies for an IN predicate. */ + uchar in_strategy; bool *get_cond_guard(int i) { @@ -413,9 +459,10 @@ public: Item_in_subselect(Item * left_expr, st_select_lex *select_lex); Item_in_subselect() :Item_exists_subselect(), left_expr_cache(0), first_execution(TRUE), - is_constant(FALSE), optimizer(0), abort_on_null(0), - pushed_cond_guards(NULL), exec_method(NOT_TRANSFORMED), upper_item(0) - {} + optimizer(0), abort_on_null(0), + pushed_cond_guards(NULL), func(NULL), in_strategy(0), + upper_item(0) + {} void cleanup(); subs_type substype() { return IN_SUBS; } void reset() @@ -425,13 +472,10 @@ public: null_value= 0; was_null= 0; } - trans_res select_transformer(JOIN *join); - trans_res select_in_like_transformer(JOIN *join, Comp_creator *func); - trans_res single_value_transformer(JOIN *join, Comp_creator *func); - trans_res row_value_transformer(JOIN * join); - trans_res single_value_in_to_exists_transformer(JOIN * join, - Comp_creator *func); - trans_res row_value_in_to_exists_transformer(JOIN * join); + bool select_transformer(JOIN *join); + bool create_in_to_exists_cond(JOIN *join_arg); + bool inject_in_to_exists_cond(JOIN *join_arg); + virtual bool exec(); longlong val_int(); double val_real(); @@ -446,11 +490,10 @@ public: bool fix_fields(THD *thd, Item **ref); void fix_after_pullout(st_select_lex *new_parent, Item **ref); void update_used_tables(); - bool setup_engine(); + bool setup_mat_engine(); bool init_left_expr_cache(); /* Inform 'this' that it was computed, and contains a valid result. */ void set_first_execution() { if (first_execution) first_execution= FALSE; } - bool is_expensive_processor(uchar *arg); bool expr_cache_is_needed(THD *thd); /* @@ -472,7 +515,6 @@ class Item_allany_subselect :public Item_in_subselect { public: chooser_compare_func_creator func_creator; - Comp_creator *func; bool all; Item_allany_subselect(Item * left_expr, chooser_compare_func_creator fc, @@ -480,7 +522,8 @@ public: // only ALL subquery has upper not subs_type substype() { return all?ALL_SUBS:ANY_SUBS; } - trans_res select_transformer(JOIN *join); + bool select_transformer(JOIN *join); + void create_comp_func(bool invert) { func= func_creator(invert); } virtual void print(String *str, enum_query_type query_type); }; @@ -818,10 +861,9 @@ public: {} ~subselect_hash_sj_engine(); - bool init_permanent(List<Item> *tmp_columns); - bool init_runtime(); + bool init(List<Item> *tmp_columns); void cleanup(); - int prepare() { return 0; } /* Override virtual function in base class. */ + int prepare(); int exec(); virtual void print(String *str, enum_query_type query_type); uint cols() diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index b324a059aad..efc1a70b9fe 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -570,25 +570,31 @@ protected: #define OPTIMIZER_SWITCH_FIRSTMATCH 64 #define OPTIMIZER_SWITCH_LOOSE_SCAN 128 #define OPTIMIZER_SWITCH_MATERIALIZATION 256 -#define OPTIMIZER_SWITCH_SEMIJOIN 512 -#define OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE 1024 -#define OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN (1<<11) -#define OPTIMIZER_SWITCH_SUBQUERY_CACHE (1<<12) -#define OPTIMIZER_SWITCH_MRR_SORT_KEYS (1<<13) -#define OPTIMIZER_SWITCH_OUTER_JOIN_WITH_CACHE (1<<14) -#define OPTIMIZER_SWITCH_SEMIJOIN_WITH_CACHE (1<<15) -#define OPTIMIZER_SWITCH_JOIN_CACHE_INCREMENTAL (1<<16) -#define OPTIMIZER_SWITCH_JOIN_CACHE_HASHED (1<<17) -#define OPTIMIZER_SWITCH_JOIN_CACHE_BKA (1<<18) +#define OPTIMIZER_SWITCH_IN_TO_EXISTS 512 +#define OPTIMIZER_SWITCH_SEMIJOIN 1024 +#define OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE (1<<11) +#define OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN (1<<12) +#define OPTIMIZER_SWITCH_SUBQUERY_CACHE (1<<13) +#define OPTIMIZER_SWITCH_MRR_SORT_KEYS (1<<14) +#define OPTIMIZER_SWITCH_OUTER_JOIN_WITH_CACHE (1<<15) +#define OPTIMIZER_SWITCH_SEMIJOIN_WITH_CACHE (1<<16) +#define OPTIMIZER_SWITCH_JOIN_CACHE_INCREMENTAL (1<<17) +#define OPTIMIZER_SWITCH_JOIN_CACHE_HASHED (1<<18) +#define OPTIMIZER_SWITCH_JOIN_CACHE_BKA (1<<19) #ifdef DBUG_OFF -# define OPTIMIZER_SWITCH_LAST (1<<19) -#else -# define OPTIMIZER_SWITCH_TABLE_ELIMINATION (1<<19) # define OPTIMIZER_SWITCH_LAST (1<<20) +#else +# define OPTIMIZER_SWITCH_TABLE_ELIMINATION (1<<20) +# define OPTIMIZER_SWITCH_LAST (1<<21) #endif #ifdef DBUG_OFF /* The following must be kept in sync with optimizer_switch_str in mysqld.cc */ +/* +TODO: Materialization is off by default to mimic 5.1/5.2 behavior. +Once cost based choice between materialization and in-to-exists should be +enabled by default, add OPTIMIZER_SWITCH_MATERIALIZATION +*/ # define OPTIMIZER_SWITCH_DEFAULT (OPTIMIZER_SWITCH_INDEX_MERGE | \ OPTIMIZER_SWITCH_INDEX_MERGE_UNION | \ OPTIMIZER_SWITCH_INDEX_MERGE_SORT_UNION | \ @@ -596,7 +602,7 @@ protected: OPTIMIZER_SWITCH_INDEX_COND_PUSHDOWN | \ OPTIMIZER_SWITCH_FIRSTMATCH | \ OPTIMIZER_SWITCH_LOOSE_SCAN | \ - OPTIMIZER_SWITCH_MATERIALIZATION | \ + OPTIMIZER_SWITCH_IN_TO_EXISTS | \ OPTIMIZER_SWITCH_SEMIJOIN | \ OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE|\ OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN|\ @@ -615,7 +621,7 @@ protected: OPTIMIZER_SWITCH_TABLE_ELIMINATION | \ OPTIMIZER_SWITCH_FIRSTMATCH | \ OPTIMIZER_SWITCH_LOOSE_SCAN | \ - OPTIMIZER_SWITCH_MATERIALIZATION | \ + OPTIMIZER_SWITCH_IN_TO_EXISTS | \ OPTIMIZER_SWITCH_SEMIJOIN | \ OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE|\ OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN|\ diff --git a/sql/mysqld.cc b/sql/mysqld.cc index 67d4f811efa..2385fe6ef48 100644 --- a/sql/mysqld.cc +++ b/sql/mysqld.cc @@ -341,7 +341,7 @@ static const char *optimizer_switch_names[]= "index_merge","index_merge_union","index_merge_sort_union", "index_merge_intersection","index_merge_sort_intersection", "index_condition_pushdown", - "firstmatch","loosescan","materialization", "semijoin", + "firstmatch","loosescan","materialization","in_to_exists","semijoin", "partial_match_rowid_merge", "partial_match_table_scan", "subquery_cache", @@ -369,6 +369,7 @@ static const unsigned int optimizer_switch_names_len[]= sizeof("firstmatch") - 1, sizeof("loosescan") - 1, sizeof("materialization") - 1, + sizeof("in_to_exists") - 1, sizeof("semijoin") - 1, sizeof("partial_match_rowid_merge") - 1, sizeof("partial_match_table_scan") - 1, @@ -474,7 +475,8 @@ static const char *optimizer_switch_str="index_merge=on,index_merge_union=on," "index_condition_pushdown=on," "firstmatch=on," "loosescan=on," - "materialization=on," + "materialization=off," + "in_to_exists=on," "semijoin=on," "partial_match_rowid_merge=on," "partial_match_table_scan=on," @@ -7407,7 +7409,7 @@ thread is in the relay logs.", "optimizer_switch=option=val[,option=val...], where option={index_merge, " "index_merge_union, index_merge_sort_union, index_merge_intersection, " "index_merge_sort_intersection, " - "index_condition_pushdown, firstmatch, loosescan, materialization, " + "index_condition_pushdown, firstmatch, loosescan, materialization, in_to_exists, " "semijoin, partial_match_rowid_merge, partial_match_table_scan, " "subquery_cache, outer_join_with_cache, semijoin_with_cache, " "join_cache_incremental, join_cache_hashed, join_cache_bka" diff --git a/sql/opt_subselect.cc b/sql/opt_subselect.cc index 5428467b850..bdf5175fc8b 100644 --- a/sql/opt_subselect.cc +++ b/sql/opt_subselect.cc @@ -29,6 +29,10 @@ static TABLE_LIST *alloc_join_nest(THD *thd); static void fix_list_after_tbl_changes(SELECT_LEX *new_parent, List<TABLE_LIST> *tlist); static uint get_tmp_table_rec_length(List<Item> &items); +static double get_tmp_table_lookup_cost(THD *thd, ha_rows row_count, + uint row_size); +static double get_tmp_table_write_cost(THD *thd, ha_rows row_count, + uint row_size); bool find_eq_ref_candidate(TABLE *table, table_map sj_inner_tables); static SJ_MATERIALIZATION_INFO * at_sjmat_pos(const JOIN *join, table_map remaining_tables, const JOIN_TAB *tab, @@ -67,6 +71,7 @@ int check_and_do_in_subquery_rewrites(JOIN *join) { THD *thd=join->thd; st_select_lex *select_lex= join->select_lex; + st_select_lex_unit* parent_unit= select_lex->master_unit(); DBUG_ENTER("check_and_do_in_subquery_rewrites"); /* If @@ -84,8 +89,8 @@ int check_and_do_in_subquery_rewrites(JOIN *join) TODO: for PS, make the whole block execute only on the first execution */ Item_subselect *subselect; - if (!thd->lex->view_prepare_mode && // (1) - (subselect= select_lex->master_unit()->item)) // (2) + if (!thd->lex->view_prepare_mode && // (1) + (subselect= parent_unit->item)) // (2) { Item_in_subselect *in_subs= NULL; if (subselect->substype() == Item_subselect::IN_SUBS) @@ -129,6 +134,15 @@ int check_and_do_in_subquery_rewrites(JOIN *join) if (failure) DBUG_RETURN(-1); /* purecov: deadcode */ } + if (select_lex == parent_unit->fake_select_lex) + { + /* + The join and its select_lex object represent the 'fake' select used + to compute the result of a UNION. + */ + DBUG_RETURN(0); + } + DBUG_PRINT("info", ("Checking if subq can be converted to semi-join")); /* Check if we're in subquery that is a candidate for flattening into a @@ -154,8 +168,8 @@ int check_and_do_in_subquery_rewrites(JOIN *join) !join->having && !select_lex->with_sum_func && // 4 thd->thd_marker.emb_on_expr_nest && // 5 select_lex->outer_select()->join && // 6 - select_lex->master_unit()->first_select()->leaf_tables && // 7 - in_subs->exec_method == Item_in_subselect::NOT_TRANSFORMED && // 8 + parent_unit->first_select()->leaf_tables && // 7 + !in_subs->in_strategy && // 8 select_lex->outer_select()->leaf_tables && // 9 !((join->select_options | // 10 select_lex->outer_select()->join->select_options) // 10 @@ -175,63 +189,80 @@ int check_and_do_in_subquery_rewrites(JOIN *join) else { DBUG_PRINT("info", ("Subquery can't be converted to semi-join")); - /* - Check if the subquery predicate can be executed via materialization. - The required conditions are: - 1. Subquery predicate is an IN/=ANY subq predicate - 2. Subquery is a single SELECT (not a UNION) - 3. Subquery is not a table-less query. In this case there is no - point in materializing. - 3A The upper query is not a table-less SELECT ... FROM DUAL. We + /* Test if the user has set a legal combination of optimizer switches. */ + if (!optimizer_flag(thd, OPTIMIZER_SWITCH_IN_TO_EXISTS) && + !optimizer_flag(thd, OPTIMIZER_SWITCH_MATERIALIZATION)) + my_error(ER_ILLEGAL_SUBQUERY_OPTIMIZER_SWITCHES, MYF(0)); + + if (in_subs) + { + /* Subquery predicate is an IN/=ANY predicate. */ + if (optimizer_flag(thd, OPTIMIZER_SWITCH_IN_TO_EXISTS)) + in_subs->in_strategy|= SUBS_IN_TO_EXISTS; + if (optimizer_flag(thd, OPTIMIZER_SWITCH_MATERIALIZATION)) + in_subs->in_strategy|= SUBS_MATERIALIZATION; + + /* + Check if the subquery predicate can be executed via materialization. + The required conditions are: + 1. Subquery is a single SELECT (not a UNION) + 2. Subquery is not a table-less query. In this case there is no + point in materializing. + 2A The upper query is not a table-less SELECT ... FROM DUAL. We can't do materialization for SELECT .. FROM DUAL because it does not call setup_subquery_materialization(). We could make SELECT ... FROM DUAL call that function but that doesn't seem to be the case that is worth handling. - 4. Either the subquery predicate is a top-level predicate, or at - least one partial match strategy is enabled. If no partial match - strategy is enabled, then materialization cannot be used for - non-top-level queries because it cannot handle NULLs correctly. - 5. Subquery is non-correlated - TODO: - This is an overly restrictive condition. It can be extended to: - (Subquery is non-correlated || - Subquery is correlated to any query outer to IN predicate || - (Subquery is correlated to the immediate outer query && - Subquery !contains {GROUP BY, ORDER BY [LIMIT], - aggregate functions}) && subquery predicate is not under "NOT IN")) - 6. No execution method was already chosen (by a prepared statement). - - (*) The subquery must be part of a SELECT statement. The current - condition also excludes multi-table update statements. - - Determine whether we will perform subquery materialization before - calling the IN=>EXISTS transformation, so that we know whether to - perform the whole transformation or only that part of it which wraps - Item_in_subselect in an Item_in_optimizer. - */ - if (optimizer_flag(thd, OPTIMIZER_SWITCH_MATERIALIZATION) && - in_subs && // 1 - !select_lex->is_part_of_union() && // 2 - select_lex->master_unit()->first_select()->leaf_tables && // 3 - thd->lex->sql_command == SQLCOM_SELECT && // * - select_lex->outer_select()->leaf_tables && // 3A - subquery_types_allow_materialization(in_subs) && - // psergey-todo: duplicated_subselect_card_check: where it's done? - (in_subs->is_top_level_item() || - optimizer_flag(thd, OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE) || - optimizer_flag(thd, OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN)) &&//4 - !in_subs->is_correlated && // 5 - in_subs->exec_method == Item_in_subselect::NOT_TRANSFORMED) // 6 - { - in_subs->exec_method= Item_in_subselect::MATERIALIZATION; - } + 3. Either the subquery predicate is a top-level predicate, or at + least one partial match strategy is enabled. If no partial match + strategy is enabled, then materialization cannot be used for + non-top-level queries because it cannot handle NULLs correctly. + 4. Subquery is non-correlated + TODO: + This is an overly restrictive condition. It can be extended to: + (Subquery is non-correlated || + Subquery is correlated to any query outer to IN predicate || + (Subquery is correlated to the immediate outer query && + Subquery !contains {GROUP BY, ORDER BY [LIMIT], + aggregate functions}) && subquery predicate is not under "NOT IN")) + + (*) The subquery must be part of a SELECT statement. The current + condition also excludes multi-table update statements. + */ + if (!(in_subs->in_strategy & SUBS_MATERIALIZATION && + !select_lex->is_part_of_union() && // 1 + parent_unit->first_select()->leaf_tables && // 2 + thd->lex->sql_command == SQLCOM_SELECT && // * + select_lex->outer_select()->leaf_tables && // 2A + subquery_types_allow_materialization(in_subs) && + // psergey-todo: duplicated_subselect_card_check: where it's done? + (in_subs->is_top_level_item() || //3 + optimizer_flag(thd, + OPTIMIZER_SWITCH_PARTIAL_MATCH_ROWID_MERGE) || //3 + optimizer_flag(thd, + OPTIMIZER_SWITCH_PARTIAL_MATCH_TABLE_SCAN)) && //3 + !in_subs->is_correlated)) //4 + { + /* Materialization is not possible based on syntactic properties. */ + in_subs->in_strategy&= ~SUBS_MATERIALIZATION; + } - Item_subselect::trans_res trans_res; - if ((trans_res= subselect->select_transformer(join)) != - Item_subselect::RES_OK) - { - DBUG_RETURN((trans_res == Item_subselect::RES_ERROR)); + if (!in_subs->in_strategy) + { + /* + If neither materialization is possible, nor the user chose + IN-TO-EXISTS, choose IN-TO-EXISTS as the only universal strategy. + */ + in_subs->in_strategy|= SUBS_IN_TO_EXISTS; + } } + + /* + Transform each subquery predicate according to its overloaded + transformer. + */ + if (subselect->select_transformer(join)) + DBUG_RETURN(-11); } } DBUG_RETURN(0); @@ -473,18 +504,17 @@ skip_conversion: for (; in_subq!= in_subq_end; in_subq++) { JOIN *child_join= (*in_subq)->unit->first_select()->join; - Item_subselect::trans_res res; (*in_subq)->changed= 0; (*in_subq)->fixed= 0; SELECT_LEX *save_select_lex= thd->lex->current_select; thd->lex->current_select= (*in_subq)->unit->first_select(); - res= (*in_subq)->select_transformer(child_join); + bool res= (*in_subq)->select_transformer(child_join); thd->lex->current_select= save_select_lex; - if (res == Item_subselect::RES_ERROR) + if (res) DBUG_RETURN(TRUE); (*in_subq)->changed= 1; @@ -509,6 +539,15 @@ skip_conversion: FALSE)) DBUG_RETURN(TRUE); } + /* + Revert to the IN->EXISTS strategy in the rare case when the subquery could + not be flattened. + TODO: This is a limitation done for simplicity. Such subqueries could also + be executed via materialization. In order to determine this, we should + re-run the test for materialization that was done in + check_and_do_in_subquery_rewrites. + */ + (*in_subq)->in_strategy= SUBS_IN_TO_EXISTS; } if (arena) @@ -769,8 +808,7 @@ static bool convert_subq_to_sj(JOIN *parent_join, Item_in_subselect *subq_pred) /* 3. Remove the original subquery predicate from the WHERE/ON */ // The subqueries were replaced for Item_int(1) earlier - subq_pred->exec_method= - Item_in_subselect::SEMI_JOIN; // for subsequent executions + subq_pred->in_strategy= SUBS_SEMI_JOIN; // for subsequent executions /*TODO: also reset the 'with_subselect' there. */ /* n. Adjust the parent_join->tables counter */ @@ -1167,8 +1205,8 @@ bool optimize_semijoin_nests(JOIN *join, table_map all_table_map) sjm->tables= n_tables; sjm->is_used= FALSE; double subjoin_out_rows, subjoin_read_time; - get_partial_join_cost(join, n_tables, - &subjoin_read_time, &subjoin_out_rows); + join->get_partial_join_cost(n_tables + join->const_tables, + &subjoin_read_time, &subjoin_out_rows); sjm->materialization_cost.convert_from_cost(subjoin_read_time); sjm->rows= subjoin_out_rows; @@ -1216,17 +1254,16 @@ bool optimize_semijoin_nests(JOIN *join, table_map all_table_map) Calculate temporary table parameters and usage costs */ uint rowlen= get_tmp_table_rec_length(right_expr_list); - double lookup_cost; - if (rowlen * subjoin_out_rows< join->thd->variables.max_heap_table_size) - lookup_cost= HEAP_TEMPTABLE_LOOKUP_COST; - else - lookup_cost= DISK_TEMPTABLE_LOOKUP_COST; + double lookup_cost= get_tmp_table_lookup_cost(join->thd, + subjoin_out_rows, rowlen); + double write_cost= get_tmp_table_write_cost(join->thd, + subjoin_out_rows, rowlen); /* Let materialization cost include the cost to write the data into the temporary table: */ - sjm->materialization_cost.add_io(subjoin_out_rows, lookup_cost); + sjm->materialization_cost.add_io(subjoin_out_rows, write_cost); /* Set the cost to do a full scan of the temptable (will need this to @@ -1301,6 +1338,49 @@ static uint get_tmp_table_rec_length(List<Item> &items) return len; } + +/** + The cost of a lookup into a unique hash/btree index on a temporary table + with 'row_count' rows each of size 'row_size'. + + @param thd current query context + @param row_count number of rows in the temp table + @param row_size average size in bytes of the rows + + @return the cost of one lookup +*/ + +static double get_tmp_table_lookup_cost(THD *thd, ha_rows row_count, uint row_size) +{ + if (row_count * row_size > thd->variables.max_heap_table_size) + return (double) DISK_TEMPTABLE_LOOKUP_COST; + else + return (double) HEAP_TEMPTABLE_LOOKUP_COST; +} + +/** + The cost of writing a row into a temporary table with 'row_count' unique + rows each of size 'row_size'. + + @param thd current query context + @param row_count number of rows in the temp table + @param row_size average size in bytes of the rows + + @return the cost of writing one row +*/ + +static double get_tmp_table_write_cost(THD *thd, ha_rows row_count, uint row_size) +{ + double lookup_cost= get_tmp_table_lookup_cost(thd, row_count, row_size); + /* + TODO: + This is an optimistic estimate. Add additional costs resulting from + actually writing the row to memory/disk and possible index reorganization. + */ + return lookup_cost; +} + + //psergey-todo: is the below a kind of table elimination?? /* Check if table's KEYUSE elements have an eq_ref(outer_tables) candidate @@ -1830,15 +1910,15 @@ void advance_sj_state(JOIN *join, table_map remaining_tables, - sj_inner_fanout*sj_outer_fanout lookups. */ - double one_lookup_cost; - if (sj_outer_fanout*temptable_rec_size > - join->thd->variables.max_heap_table_size) - one_lookup_cost= DISK_TEMPTABLE_LOOKUP_COST; - else - one_lookup_cost= HEAP_TEMPTABLE_LOOKUP_COST; + double one_lookup_cost= get_tmp_table_lookup_cost(join->thd, + sj_outer_fanout, + temptable_rec_size); + double one_write_cost= get_tmp_table_write_cost(join->thd, + sj_outer_fanout, + temptable_rec_size); double write_cost= join->positions[first_tab].prefix_record_count* - sj_outer_fanout * one_lookup_cost; + sj_outer_fanout * one_write_cost; double full_lookup_cost= join->positions[first_tab].prefix_record_count* sj_outer_fanout* sj_inner_fanout * one_lookup_cost; @@ -3357,9 +3437,23 @@ int rewrite_to_index_subquery_engine(JOIN *join) JOIN_TAB* join_tab=join->join_tab; SELECT_LEX_UNIT *unit= join->unit; DBUG_ENTER("rewrite_to_index_subquery_engine"); + /* is this simple IN subquery? */ + /* TODO: In order to use these more efficient subquery engines in more cases, + the following problems need to be solved: + - the code that removes GROUP BY (group_list), also adds an ORDER BY + (order), thus GROUP BY queries (almost?) never pass through this branch. + Solution: remove the test below '!join->order', because we remove the + ORDER clase for subqueries anyway. + - in order to set a more efficient engine, the optimizer needs to both + decide to remove GROUP BY, *and* select one of the JT_[EQ_]REF[_OR_NULL] + access methods, *and* loose scan should be more expensive or + inapliccable. When is that possible? + - Consider expanding the applicability of this rewrite for loose scan + for group by queries. + */ if (!join->group_list && !join->order && join->unit->item && join->unit->item->substype() == Item_subselect::IN_SUBS && @@ -3500,3 +3594,342 @@ static void remove_subq_pushed_predicates(JOIN *join, Item **where) } +/** + Optimize all subqueries of a query that have were flattened into a semijoin. + + @details + Optimize all immediate children subqueries of a query. + + This phase must be called after substitute_for_best_equal_field() because + that function may replace items with other items from a multiple equality, + and we need to reference the correct items in the index access method of the + IN predicate. + + @return Operation status + @retval FALSE success. + @retval TRUE error occurred. +*/ + +bool JOIN::optimize_unflattened_subqueries() +{ + return select_lex->optimize_unflattened_subqueries(); +} + + +/** + Choose an optimal strategy to execute an IN/ALL/ANY subquery predicate + based on cost. + + @param join_tables the set of tables joined in the subquery + + @notes + The method chooses between the materialization and IN=>EXISTS rewrite + strategies for the execution of a non-flattened subquery IN predicate. + The cost-based decision is made as follows: + + 1. compute materialize_strategy_cost based on the unmodified subquery + 2. reoptimize the subquery taking into account the IN-EXISTS predicates + 3. compute in_exists_strategy_cost based on the reoptimized plan + 4. compare and set the cheaper strategy + if (materialize_strategy_cost >= in_exists_strategy_cost) + in_strategy = MATERIALIZATION + else + in_strategy = IN_TO_EXISTS + 5. if in_strategy = MATERIALIZATION and it is not possible to initialize it + revert to IN_TO_EXISTS + 6. if (in_strategy == MATERIALIZATION) + revert the subquery plan to the original one before reoptimizing + else + inject the IN=>EXISTS predicates into the new EXISTS subquery plan + + The implementation itself is a bit more complicated because it takes into + account two more factors: + - whether the user allowed both strategies through an optimizer_switch, and + - if materialization was the cheaper strategy, whether it can be executed + or not. + + @retval FALSE success. + @retval TRUE error occurred. +*/ + +bool JOIN::choose_subquery_plan(table_map join_tables) +{ + Query_plan_state save_qep; /* The original QEP of the subquery. */ + enum_reopt_result reopt_result= REOPT_NONE; + Item_in_subselect *in_subs; + + if (select_lex->master_unit()->item && + select_lex->master_unit()->item->is_in_predicate()) + { + in_subs= (Item_in_subselect*) select_lex->master_unit()->item; + if (in_subs->create_in_to_exists_cond(this)) + return true; + } + else + return false; + + DBUG_ASSERT(in_subs->in_strategy); /* A strategy must be chosen earlier. */ + DBUG_ASSERT(in_to_exists_where || in_to_exists_having); + DBUG_ASSERT(!in_to_exists_where || in_to_exists_where->fixed); + DBUG_ASSERT(!in_to_exists_having || in_to_exists_having->fixed); + + /* + Compute and compare the costs of materialization and in-exists if both + strategies are possible and allowed by the user (checked during the prepare + phase. + */ + if (in_subs->in_strategy & SUBS_MATERIALIZATION && + in_subs->in_strategy & SUBS_IN_TO_EXISTS) + { + JOIN *outer_join; + JOIN *inner_join= this; + /* Number of (partial) rows of the outer JOIN filtered by the IN predicate. */ + double outer_record_count; + /* Number of unique value combinations filtered by the IN predicate. */ + double outer_lookup_keys; + /* Cost and row count of the unmodified subquery. */ + double inner_read_time_1, inner_record_count_1; + /* Cost and row count of the subquery with injected IN-EXISTS predicates. */ + double inner_read_time_2; + /* The cost to compute IN via materialization. */ + double materialize_strategy_cost; + /* The cost of the IN->EXISTS strategy. */ + double in_exists_strategy_cost; + double dummy; + + /* + A. Estimate the number of rows of the outer table that will be filtered + by the IN predicate. + */ + outer_join= unit->outer_select() ? unit->outer_select()->join : NULL; + if (outer_join) + { + uint outer_partial_plan_len; + /* + Make_cond_for_table is called for predicates only in the WHERE/ON + clauses. In all other cases, predicates are not pushed to any + JOIN_TAB, and their joi_tab_idx remains MAX_TABLES. Such predicates + are evaluated for each complete row of the outer join. + */ + outer_partial_plan_len= (in_subs->get_join_tab_idx() == MAX_TABLES) ? + outer_join->tables : + in_subs->get_join_tab_idx() + 1; + outer_join->get_partial_join_cost(outer_partial_plan_len, &dummy, + &outer_record_count); + if (outer_join->tables > outer_join->const_tables) + outer_lookup_keys= prev_record_reads(outer_join->best_positions, + outer_partial_plan_len, + in_subs->used_tables()); + else + { + /* If all tables are constant, positions is undefined. */ + outer_lookup_keys= 1; + } + } + else + { + /* + TODO: outer_join can be NULL for DELETE statements. + How to compute its cost? + */ + outer_record_count= 1; + outer_lookup_keys=1; + } + DBUG_ASSERT(outer_lookup_keys <= outer_record_count); + + /* + B. Estimate the cost and number of records of the subquery both + unmodified, and with injected IN->EXISTS predicates. + */ + inner_read_time_1= inner_join->best_read; + inner_record_count_1= inner_join->record_count; + + if (in_to_exists_where && const_tables != tables) + { + /* + Re-optimize and cost the subquery taking into account the IN-EXISTS + conditions. + */ + reopt_result= reoptimize(in_to_exists_where, join_tables, &save_qep); + if (reopt_result == REOPT_ERROR) + return TRUE; + + /* inner_read_time_2 above is a dummy, get the correct total join cost. */ + inner_read_time_2= inner_join->best_read; + + } + else + { + /* Reoptimization would not produce any better plan. */ + inner_read_time_2= inner_read_time_1; + } + + /* + C. Compute execution costs. + */ + /* C.1 Compute the cost of the materialization strategy. */ + uint rowlen= get_tmp_table_rec_length(unit->first_select()->item_list); + /* The cost of writing one row into the temporary table. */ + double write_cost= get_tmp_table_write_cost(thd, inner_record_count_1, + rowlen); + /* The cost of a lookup into the unique index of the materialized table. */ + double lookup_cost= get_tmp_table_lookup_cost(thd, inner_record_count_1, + rowlen); + /* + The cost of executing the subquery and storing its result in an indexed + temporary table. + */ + double materialization_cost= inner_read_time_1 + + write_cost * inner_record_count_1; + + materialize_strategy_cost= materialization_cost + + outer_record_count * lookup_cost; + + /* C.2 Compute the cost of the IN=>EXISTS strategy. */ + in_exists_strategy_cost= outer_lookup_keys * inner_read_time_2; + + /* C.3 Compare the costs and choose the cheaper strategy. */ + if (materialize_strategy_cost >= in_exists_strategy_cost) + in_subs->in_strategy&= ~SUBS_MATERIALIZATION; + else + in_subs->in_strategy&= ~SUBS_IN_TO_EXISTS; + } + + /* + If (1) materialization is a possible strategy based on semantic analysis + during the prepare phase, then if + (2) it is more expensive than the IN->EXISTS transformation, and + (3) it is not possible to create usable indexes for the materialization + strategy, + fall back to IN->EXISTS. + otherwise + use materialization. + */ + if (in_subs->in_strategy & SUBS_MATERIALIZATION && + in_subs->setup_mat_engine()) + { + /* + If materialization was the cheaper or the only user-selected strategy, + but it is not possible to execute it due to limitations in the + implementation, fall back to IN-TO-EXISTS. + */ + in_subs->in_strategy&= ~SUBS_MATERIALIZATION; + in_subs->in_strategy|= SUBS_IN_TO_EXISTS; + } + + if (in_subs->in_strategy & SUBS_MATERIALIZATION) + { + /* Restore the original query plan used for materialization. */ + if (reopt_result == REOPT_NEW_PLAN) + restore_query_plan(&save_qep); + + /* TODO: should we set/unset this flag for both select_lex and its unit? */ + in_subs->unit->uncacheable&= ~UNCACHEABLE_DEPENDENT; + select_lex->uncacheable&= ~UNCACHEABLE_DEPENDENT; + + /* + Reset the "LIMIT 1" set in Item_exists_subselect::fix_length_and_dec. + TODO: + Currently we set the subquery LIMIT to infinity, and this is correct + because we forbid at parse time LIMIT inside IN subqueries (see + Item_in_subselect::test_limit). However, once we allow this, here + we should set the correct limit if given in the query. + */ + in_subs->unit->global_parameters->select_limit= NULL; + in_subs->unit->set_limit(unit->global_parameters); + /* + Set the limit of this JOIN object as well, because normally its being + set in the beginning of JOIN::optimize, which was already done. + */ + select_limit= in_subs->unit->select_limit_cnt; + } + else if (in_subs->in_strategy & SUBS_IN_TO_EXISTS) + { + if (reopt_result == REOPT_NONE && in_to_exists_where && + const_tables != tables) + { + /* + The subquery was not reoptimized either because the user allowed only the + IN-EXISTS strategy, or because materialization was not possible based on + semantic analysis. Clenup the original plan and reoptimize. + */ + for (uint i= 0; i < tables; i++) + { + join_tab[i].keyuse= NULL; + join_tab[i].checked_keys.clear_all(); + } + if ((reopt_result= reoptimize(in_to_exists_where, join_tables, NULL)) == + REOPT_ERROR) + return TRUE; + } + + if (in_subs->inject_in_to_exists_cond(this)) + return TRUE; + } + else + DBUG_ASSERT(FALSE); + + return FALSE; +} + + +/** + Choose a query plan for a table-less subquery. + + @notes + + @retval FALSE success. + @retval TRUE error occurred. +*/ + +bool JOIN::choose_tableless_subquery_plan() +{ + DBUG_ASSERT(!tables_list || !tables); + if (select_lex->master_unit()->item) + { + DBUG_ASSERT(select_lex->master_unit()->item->type() == + Item::SUBSELECT_ITEM); + Item_subselect *subs_predicate= select_lex->master_unit()->item; + + /* + If the optimizer determined that his query has an empty result, + in most cases the subquery predicate is a known constant value - + either FALSE or NULL. The implementation of Item_subselect::reset() + determines which one. + */ + if (zero_result_cause) + { + if (!implicit_grouping) + { + /* + Both group by queries and non-group by queries without aggregate + functions produce empty subquery result. + */ + subs_predicate->reset(); + subs_predicate->make_const(); + return FALSE; + } + + /* TODO: + A further optimization is possible when a non-group query with + MIN/MAX/COUNT is optimized by opt_sum_query. Then, if there are + only MIN/MAX functions over an empty result set, the subquery + result is a NULL value/row, thus the value of subs_predicate is + NULL. + */ + } + + if (subs_predicate->is_in_predicate()) + { + Item_in_subselect *in_subs; + in_subs= (Item_in_subselect*) subs_predicate; + in_subs->in_strategy= SUBS_IN_TO_EXISTS; + if (in_subs->create_in_to_exists_cond(this) || + in_subs->inject_in_to_exists_cond(this)) + return TRUE; + tmp_having= having; + } + } + return FALSE; +} + diff --git a/sql/share/errmsg.txt b/sql/share/errmsg.txt index 54061931d5f..252c69afe6c 100644 --- a/sql/share/errmsg.txt +++ b/sql/share/errmsg.txt @@ -6247,3 +6247,5 @@ ER_UNKNOWN_OPTION eng "Unknown option '%-.64s'" ER_BAD_OPTION_VALUE eng "Incorrect value '%-.64s' for option '%-.64s'" +ER_ILLEGAL_SUBQUERY_OPTIMIZER_SWITCHES + eng "At least one of the 'in_to_exists' or 'materialization' optimizer_switch flags must be 'on'." diff --git a/sql/sql_class.cc b/sql/sql_class.cc index 084e2c8d78c..2a5d5214658 100644 --- a/sql/sql_class.cc +++ b/sql/sql_class.cc @@ -2689,6 +2689,7 @@ void Query_arena::free_items() for (; free_list; free_list= next) { next= free_list->next; + DBUG_ASSERT(free_list != next); free_list->delete_self(); } /* Postcondition: free_list is 0 */ @@ -3132,6 +3133,7 @@ void TMP_TABLE_PARAM::init() table_charset= 0; precomputed_group_by= 0; bit_fields_as_long= 0; + materialized_subquery= 0; skip_create_table= 0; DBUG_VOID_RETURN; } diff --git a/sql/sql_class.h b/sql/sql_class.h index 4b49fbcd3ff..50a286ac06a 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -2951,6 +2951,8 @@ public: uint convert_blob_length; CHARSET_INFO *table_charset; bool schema_table; + /* TRUE if the temp table is created for subquery materialization. */ + bool materialized_subquery; /* True if GROUP BY and its aggregate functions are already computed by a table access method (e.g. by loose index scan). In this case @@ -2974,8 +2976,8 @@ public: TMP_TABLE_PARAM() :copy_field(0), group_parts(0), group_length(0), group_null_parts(0), convert_blob_length(0), - schema_table(0), precomputed_group_by(0), force_copy_fields(0), - bit_fields_as_long(0), skip_create_table(0) + schema_table(0), materialized_subquery(0), precomputed_group_by(0), + force_copy_fields(0), bit_fields_as_long(0), skip_create_table(0) {} ~TMP_TABLE_PARAM() { @@ -3009,6 +3011,7 @@ public: virtual bool create_result_table(THD *thd, List<Item> *column_types, bool is_distinct, ulonglong options, const char *alias, bool bit_fields_as_long); + TMP_TABLE_PARAM *get_tmp_table_param() { return &tmp_table_param; } }; /* Base subselect interface class */ @@ -3072,7 +3075,7 @@ protected: void reset(); public: - select_materialize_with_stats() {} + select_materialize_with_stats() { tmp_table_param.init(); } virtual bool create_result_table(THD *thd, List<Item> *column_types, bool is_distinct, ulonglong options, const char *alias, bool bit_fields_as_long); diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index 5564d628594..9d5f99a57ec 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -92,6 +92,10 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, } } + /* Apply the IN=>EXISTS transformation to all subqueries and optimize them. */ + if (select_lex->optimize_unflattened_subqueries()) + DBUG_RETURN(TRUE); + const_cond= (!conds || conds->const_item()); safe_update=test(thd->options & OPTION_SAFE_UPDATES); if (safe_update && const_cond) diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 4737b64c94d..e8a724cea82 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1735,17 +1735,29 @@ void st_select_lex_node::fast_exclude() } + +/* + Exclude a node from the tree lex structure, but leave it in the global + list of nodes. +*/ + +void st_select_lex_node::exclude_from_tree() +{ + if ((*prev= next)) + next->prev= prev; +} + + /* - excluding select_lex structure (except first (first select can't be + Exclude select_lex structure (except first (first select can't be deleted, because it is most upper select)) */ void st_select_lex_node::exclude() { - //exclude from global list + /* exclude from global list */ fast_exclude(); - //exclude from other structures - if ((*prev= next)) - next->prev= prev; + /* exclude from other structures */ + exclude_from_tree(); /* We do not need following statements, because prev pointer of first list element point to master->slave @@ -2145,8 +2157,8 @@ void st_select_lex::print_limit(THD *thd, select_limit == 1, and there should be no offset_limit. */ (((subs_type == Item_subselect::IN_SUBS) && - ((Item_in_subselect*)item)->exec_method == - Item_in_subselect::MATERIALIZATION) ? + ((Item_in_subselect*)item)->in_strategy & + SUBS_MATERIALIZATION) ? TRUE : (select_limit->val_int() == 1LL) && offset_limit == 0)); @@ -3076,6 +3088,70 @@ bool st_select_lex::add_index_hint (THD *thd, char *str, uint length) str, length)); } + +bool st_select_lex::optimize_unflattened_subqueries() +{ + for (SELECT_LEX_UNIT *un= first_inner_unit(); un; un= un->next_unit()) + { + Item_subselect *subquery_predicate= un->item; + if (subquery_predicate) + { + for (SELECT_LEX *sl= un->first_select(); sl; sl= sl->next_select()) + { + JOIN *inner_join= sl->join; + SELECT_LEX *save_select= un->thd->lex->current_select; + ulonglong save_options; + int res; + /* We need only 1 row to determine existence */ + un->set_limit(un->global_parameters); + un->thd->lex->current_select= sl; + save_options= inner_join->select_options; + if (un->outer_select()->options & SELECT_DESCRIBE) + { + /* Optimize the subquery in the context of EXPLAIN. */ + set_explain_type(); + inner_join->select_options= options; + } + res= inner_join->optimize(); + inner_join->select_options= save_options; + un->thd->lex->current_select= save_select; + if (res) + return TRUE; + } + } + } + return FALSE; +} + + +/** + Set the EXPLAIN type for this subquery. +*/ + +void st_select_lex::set_explain_type() +{ + SELECT_LEX *first= master_unit()->first_select(); + /* drop UNCACHEABLE_EXPLAIN, because it is for internal usage only */ + uint8 is_uncacheable= (uncacheable & ~UNCACHEABLE_EXPLAIN); + + type= ((&master_unit()->thd->lex->select_lex == this) ? + (first_inner_unit() || next_select() ? + "PRIMARY" : "SIMPLE") : + ((this == first) ? + ((linkage == DERIVED_TABLE_TYPE) ? + "DERIVED" : + ((is_uncacheable & UNCACHEABLE_DEPENDENT) ? + "DEPENDENT SUBQUERY" : + (is_uncacheable ? "UNCACHEABLE SUBQUERY" : + "SUBQUERY"))) : + ((is_uncacheable & UNCACHEABLE_DEPENDENT) ? + "DEPENDENT UNION": + is_uncacheable ? "UNCACHEABLE UNION": + "UNION"))); + options|= SELECT_DESCRIBE; +} + + /** A routine used by the parser to decide whether we are specifying a full partitioning or if only partitions to add or to split. @@ -3093,4 +3169,3 @@ bool st_lex::is_partition_management() const (alter_info.flags == ALTER_ADD_PARTITION || alter_info.flags == ALTER_REORGANIZE_PARTITION)); } - diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 31ca121ea66..525d7c5cf46 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -439,6 +439,7 @@ public: st_select_lex_node(): linkage(UNSPECIFIED_TYPE) {} virtual ~st_select_lex_node() {} inline st_select_lex_node* get_master() { return master; } + inline void set_master(st_select_lex_node* master_arg) { master= master_arg; } virtual void init_query(); virtual void init_select(); void include_down(st_select_lex_node *upper); @@ -446,6 +447,7 @@ public: void include_standalone(st_select_lex_node *sel, st_select_lex_node **ref); void include_global(st_select_lex_node **plink); void exclude(); + void exclude_from_tree(); virtual st_select_lex_unit* master_unit()= 0; virtual st_select_lex* outer_select()= 0; @@ -846,6 +848,15 @@ public: void clear_index_hints(void) { index_hints= NULL; } bool is_part_of_union() { return master_unit()->is_union(); } + /* + Optimize all subqueries that have not been flattened into semi-joins. + This functionality is a method of SELECT_LEX instead of JOIN because + some SQL statements as DELETE do not have a corresponding JOIN object. + */ + bool optimize_unflattened_subqueries(); + /* Set the EXPLAIN type for this subquery. */ + void set_explain_type(); + private: /* current index hint kind. used in filling up index_hints */ enum index_hint_type current_index_hint_type; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index c0360828f3c..415e4100a23 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -59,21 +59,19 @@ static bool make_join_statistics(JOIN *join, TABLE_LIST *leaves, COND *conds, static bool update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse, JOIN_TAB *join_tab, uint tables, COND *conds, - COND_EQUAL *cond_equal, table_map table_map, SELECT_LEX *select_lex, st_sargable_param **sargables); +static bool sort_and_filter_keyuse(DYNAMIC_ARRAY *keyuse); static int sort_keyuse(KEYUSE *a,KEYUSE *b); static bool create_ref_for_key(JOIN *join, JOIN_TAB *j, KEYUSE *org_keyuse, table_map used_tables); -bool choose_plan(JOIN *join,table_map join_tables); - void best_access_path(JOIN *join, JOIN_TAB *s, table_map remaining_tables, uint idx, bool disable_jbuf, double record_count, POSITION *pos, POSITION *loose_scan_pos); static void optimize_straight_join(JOIN *join, table_map join_tables); static bool greedy_search(JOIN *join, table_map remaining_tables, - uint depth, uint prune_level); + uint depth, uint prune_level); static bool best_extension_by_limited_search(JOIN *join, table_map remaining_tables, uint idx, double record_count, @@ -90,7 +88,6 @@ static int join_tab_cmp_embedded_first(const void *emb, const void* ptr1, const static bool find_best(JOIN *join,table_map rest_tables,uint index, double record_count,double read_time); static uint cache_record_length(JOIN *join,uint index); -static double prev_record_reads(JOIN *join, uint idx, table_map found_ref); static bool get_best_combination(JOIN *join); static store_key *get_store_key(THD *thd, KEYUSE *keyuse, table_map used_tables, @@ -180,11 +177,13 @@ int join_read_always_key_or_null(JOIN_TAB *tab); int join_read_next_same_or_null(READ_RECORD *info); static COND *make_cond_for_table(Item *cond,table_map table, table_map used_table, + uint join_tab_idx_arg, bool exclude_expensive_cond, bool retain_ref_cond); static COND *make_cond_for_table_from_pred(Item *root_cond, Item *cond, table_map tables, table_map used_table, + uint join_tab_idx_arg, bool exclude_expensive_cond, bool retain_ref_cond); @@ -239,8 +238,6 @@ static bool update_sum_func(Item_sum **func); static void select_describe(JOIN *join, bool need_tmp_table,bool need_order, bool distinct, const char *message=NullS); static void add_group_and_distinct_keys(JOIN *join, JOIN_TAB *join_tab); -void get_partial_join_cost(JOIN *join, uint idx, double *read_time_arg, - double *record_count_arg); static uint make_join_orderinfo(JOIN *join); static int join_read_record_no_init(JOIN_TAB *tab); @@ -846,6 +843,7 @@ JOIN::optimize() "Impossible HAVING" : "Impossible WHERE"; tables= 0; error= 0; + choose_tableless_subquery_plan(); goto setup_subq_exit; } } @@ -890,12 +888,13 @@ JOIN::optimize() */ if ((res=opt_sum_query(select_lex->leaf_tables, all_fields, conds))) { - if (res == HA_ERR_KEY_NOT_FOUND) + if (res == HA_ERR_KEY_NOT_FOUND || res < 0) { DBUG_PRINT("info",("No matching min/max row")); zero_result_cause= "No matching min/max row"; tables= 0; error=0; + choose_tableless_subquery_plan(); goto setup_subq_exit; } if (res > 1) @@ -904,14 +903,7 @@ JOIN::optimize() DBUG_PRINT("error",("Error from opt_sum_query")); DBUG_RETURN(1); } - if (res < 0) - { - DBUG_PRINT("info",("No matching min/max row")); - zero_result_cause= "No matching min/max row"; - tables= 0; - error=0; - goto setup_subq_exit; - } + DBUG_PRINT("info",("Select tables optimized away")); zero_result_cause= "Select tables optimized away"; tables_list= 0; // All tables resolved @@ -929,24 +921,21 @@ JOIN::optimize() if (conds && !(thd->lex->describe & DESCRIBE_EXTENDED)) { COND *table_independent_conds= - make_cond_for_table(conds, PSEUDO_TABLE_BITS, 0, FALSE, FALSE); + make_cond_for_table(conds, PSEUDO_TABLE_BITS, 0, MAX_TABLES, FALSE, FALSE); DBUG_EXECUTE("where", print_where(table_independent_conds, "where after opt_sum_query()", QT_ORDINARY);); conds= table_independent_conds; } - goto setup_subq_exit; } } if (!tables_list) { DBUG_PRINT("info",("No tables")); error= 0; - /* Create all structures needed for materialized subquery execution. */ - if (setup_subquery_materialization()) - DBUG_RETURN(1); - DBUG_RETURN(0); + choose_tableless_subquery_plan(); + goto setup_subq_exit; } error= -1; // Error is sent to client sort_by_table= get_sort_by_table(order, group_list, select_lex->leaf_tables); @@ -1303,8 +1292,7 @@ JOIN::optimize() if (!(select_options & SELECT_DESCRIBE)) init_ftfuncs(thd, select_lex, test(order)); - /* Create all structures needed for materialized subquery execution. */ - if (setup_subquery_materialization()) + if (optimize_unflattened_subqueries()) DBUG_RETURN(1); int res; @@ -1408,6 +1396,34 @@ JOIN::optimize() if (join_tab->is_using_loose_index_scan()) tmp_table_param.precomputed_group_by= TRUE; + error= 0; + DBUG_RETURN(0); + +setup_subq_exit: + /* + Even with zero matching rows, subqueries in the HAVING clause may + need to be evaluated if there are aggregate functions in the query. + */ + if (optimize_unflattened_subqueries()) + DBUG_RETURN(1); + error= 0; + DBUG_RETURN(0); +} + + +/** + Create and initialize objects neeed for the execution of a query plan. + Evaluate constant expressions not evaluated during optimization. +*/ + +int JOIN::init_execution() +{ + DBUG_ENTER("JOIN::init_execution"); + + DBUG_ASSERT(optimized); + DBUG_ASSERT(!(select_options & SELECT_DESCRIBE)); + initialized= true; + /* Create a tmp table if distinct or if the sort is too complicated */ if (need_tmp) { @@ -1440,7 +1456,7 @@ JOIN::optimize() select_options, tmp_rows_limit, (char *) ""))) - { + { DBUG_RETURN(1); } @@ -1526,19 +1542,6 @@ JOIN::optimize() DBUG_RETURN(-1); /* purecov: inspected */ } - error= 0; - DBUG_RETURN(0); - -setup_subq_exit: - /* - Even with zero matching rows, subqueries in the HAVING clause may - need to be evaluated if there are aggregate functions in the - query. If we have planned to materialize the subquery, we need to - set it up properly before prematurely leaving optimize(). - */ - if (setup_subquery_materialization()) - DBUG_RETURN(1); - error= 0; DBUG_RETURN(0); } @@ -1887,6 +1890,16 @@ JOIN::exec() if (tables) thd->limit_found_rows= 0; + /* + Evaluate expensive constant conditions that were not evaluated during + optimization. Do not evaluate them for EXPLAIN statements as these + condtions may be arbitrarily costly, and because the optimize phase + might not have produced a complete executable plan for EXPLAINs. + */ + if (exec_const_cond && !(select_options & SELECT_DESCRIBE) && + !exec_const_cond->val_int()) + zero_result_cause= "Impossible WHERE noticed after reading const tables"; + if (zero_result_cause) { (void) return_zero_rows(this, result, select_lex->leaf_tables, @@ -1898,6 +1911,27 @@ JOIN::exec() DBUG_VOID_RETURN; } + /* + Evaluate all constant expressions with subqueries in the ORDER/GROUP clauses + to make sure that all subqueries return a single row. The evaluation itself + will trigger an error if that is not the case. + */ + if (exec_const_order_group_cond.elements && + !(select_options & SELECT_DESCRIBE)) + { + List_iterator_fast<Item> const_item_it(exec_const_order_group_cond); + Item *cur_const_item; + while ((cur_const_item= const_item_it++)) + { + cur_const_item->val_str(&cur_const_item->str_value); + if (thd->is_error()) + { + error= thd->is_error(); + DBUG_VOID_RETURN; + } + } + } + if ((this->select_lex->options & OPTION_SCHEMA_TABLE) && get_schema_tables_result(this, PROCESSED_BY_JOIN_EXEC)) DBUG_VOID_RETURN; @@ -1936,6 +1970,9 @@ JOIN::exec() DBUG_VOID_RETURN; } + if (!initialized && init_execution()) + DBUG_VOID_RETURN; + JOIN *curr_join= this; List<Item> *curr_all_fields= &all_fields; List<Item> *curr_fields_list= &fields_list; @@ -2268,7 +2305,8 @@ JOIN::exec() Item* sort_table_cond= make_cond_for_table(curr_join->tmp_having, used_tables, - (table_map)0, FALSE, FALSE); + (table_map)0, MAX_TABLES, + FALSE, FALSE); if (sort_table_cond) { if (!curr_table->select) @@ -2299,7 +2337,8 @@ JOIN::exec() QT_ORDINARY);); curr_join->tmp_having= make_cond_for_table(curr_join->tmp_having, ~ (table_map) 0, - ~used_tables, FALSE, FALSE); + ~used_tables, MAX_TABLES, + FALSE, FALSE); DBUG_EXECUTE("where",print_where(curr_join->tmp_having, "having after sort", QT_ORDINARY);); @@ -2647,51 +2686,6 @@ err: } -/** - Setup for execution all subqueries of a query, for which the optimizer - chose hash semi-join. - - @details Iterate over all subqueries of the query, and if they are under an - IN predicate, and the optimizer chose to compute it via hash semi-join: - - try to initialize all data structures needed for the materialized execution - of the IN predicate, - - if this fails, then perform the IN=>EXISTS transformation which was - previously blocked during JOIN::prepare. - - This method is part of the "code generation" query processing phase. - - This phase must be called after substitute_for_best_equal_field() because - that function may replace items with other items from a multiple equality, - and we need to reference the correct items in the index access method of the - IN predicate. - - @return Operation status - @retval FALSE success. - @retval TRUE error occurred. -*/ - -bool JOIN::setup_subquery_materialization() -{ - for (SELECT_LEX_UNIT *un= select_lex->first_inner_unit(); un; - un= un->next_unit()) - { - for (SELECT_LEX *sl= un->first_select(); sl; sl= sl->next_select()) - { - Item_subselect *subquery_predicate= sl->master_unit()->item; - if (subquery_predicate && - subquery_predicate->substype() == Item_subselect::IN_SUBS) - { - Item_in_subselect *in_subs= (Item_in_subselect*) subquery_predicate; - if (in_subs->exec_method == Item_in_subselect::MATERIALIZATION && - in_subs->setup_engine()) - return TRUE; - } - } - } - return FALSE; -} - - /***************************************************************************** Create JOIN_TABS, make a guess about the table types, Approximate how many records will be used in each table @@ -2917,10 +2911,14 @@ make_join_statistics(JOIN *join, TABLE_LIST *tables_arg, COND *conds, } if (conds || outer_join) + { if (update_ref_and_keys(join->thd, keyuse_array, stat, join->tables, - conds, join->cond_equal, - ~outer_join, join->select_lex, &sargables)) + conds, ~outer_join, join->select_lex, &sargables)) + goto error; + if (keyuse_array->elements && sort_and_filter_keyuse(keyuse_array)) goto error; + DBUG_EXECUTE("opt", print_keyuse_array(keyuse_array);); + } join->const_table_map= no_rows_const_tables; join->const_tables= const_count; @@ -3221,8 +3219,12 @@ make_join_statistics(JOIN *join, TABLE_LIST *tables_arg, COND *conds, { memcpy((uchar*) join->best_positions,(uchar*) join->positions, sizeof(POSITION)*join->const_tables); + join->record_count= 1.0; join->best_read=1.0; } + if (join->choose_subquery_plan(all_table_map & ~join->const_table_map)) + goto error; + /* Generate an execution plan from the found optimal join order. */ DBUG_RETURN(join->thd->killed || get_best_combination(join)); @@ -4174,11 +4176,10 @@ static void add_key_fields_for_nj(JOIN *join, TABLE_LIST *nested_join_table, static bool update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, - uint tables, COND *cond, COND_EQUAL *cond_equal, - table_map normal_tables, SELECT_LEX *select_lex, - SARGABLE_PARAM **sargables) + uint tables, COND *cond, table_map normal_tables, + SELECT_LEX *select_lex, SARGABLE_PARAM **sargables) { - uint and_level,i,found_eq_constant; + uint and_level,i; KEY_FIELD *key_fields, *end, *field; uint sz; uint m= max(select_lex->max_equal_elems,1); @@ -4274,67 +4275,76 @@ update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, return TRUE; } - /* - Sort the array of possible keys and remove the following key parts: - - ref if there is a keypart which is a ref and a const. - (e.g. if there is a key(a,b) and the clause is a=3 and b=7 and b=t2.d, - then we skip the key part corresponding to b=t2.d) - - keyparts without previous keyparts - (e.g. if there is a key(a,b,c) but only b < 5 (or a=2 and c < 3) is - used in the query, we drop the partial key parts from consideration). - Special treatment for ft-keys. - */ - if (keyuse->elements) - { - KEYUSE key_end,*prev,*save_pos,*use; + return FALSE; +} - my_qsort(keyuse->buffer,keyuse->elements,sizeof(KEYUSE), - (qsort_cmp) sort_keyuse); - bzero((char*) &key_end,sizeof(key_end)); /* Add for easy testing */ - if (insert_dynamic(keyuse,(uchar*) &key_end)) - return TRUE; +/** + Sort the array of possible keys and remove the following key parts: + - ref if there is a keypart which is a ref and a const. + (e.g. if there is a key(a,b) and the clause is a=3 and b=7 and b=t2.d, + then we skip the key part corresponding to b=t2.d) + - keyparts without previous keyparts + (e.g. if there is a key(a,b,c) but only b < 5 (or a=2 and c < 3) is + used in the query, we drop the partial key parts from consideration). + Special treatment for ft-keys. +*/ + +static bool sort_and_filter_keyuse(DYNAMIC_ARRAY *keyuse) +{ + KEYUSE key_end, *prev, *save_pos, *use; + uint found_eq_constant, i; + + DBUG_ASSERT(keyuse->elements); + + my_qsort(keyuse->buffer, keyuse->elements, sizeof(KEYUSE), + (qsort_cmp) sort_keyuse); - use=save_pos=dynamic_element(keyuse,0,KEYUSE*); - prev= &key_end; - found_eq_constant=0; - for (i=0 ; i < keyuse->elements-1 ; i++,use++) + bzero((char*) &key_end, sizeof(key_end)); /* Add for easy testing */ + if (insert_dynamic(keyuse, (uchar*) &key_end)) + return TRUE; + + use= save_pos= dynamic_element(keyuse,0,KEYUSE*); + prev= &key_end; + found_eq_constant= 0; + + for (i=0 ; i < keyuse->elements-1 ; i++,use++) + { + if (!use->used_tables && use->optimize != KEY_OPTIMIZE_REF_OR_NULL) + use->table->const_key_parts[use->key]|= use->keypart_map; + if (use->keypart != FT_KEYPART) { - if (!use->used_tables && use->optimize != KEY_OPTIMIZE_REF_OR_NULL) - use->table->const_key_parts[use->key]|= use->keypart_map; - if (use->keypart != FT_KEYPART) + if (use->key == prev->key && use->table == prev->table) { - if (use->key == prev->key && use->table == prev->table) - { - if (prev->keypart+1 < use->keypart || - (prev->keypart == use->keypart && found_eq_constant)) - continue; /* remove */ - } - else if (use->keypart != 0) // First found must be 0 - continue; + if (prev->keypart+1 < use->keypart || + (prev->keypart == use->keypart && found_eq_constant)) + continue; /* remove */ } + else if (use->keypart != 0) // First found must be 0 + continue; + } #ifdef HAVE_valgrind - /* Valgrind complains about overlapped memcpy when save_pos==use. */ - if (save_pos != use) + /* Valgrind complains about overlapped memcpy when save_pos==use. */ + if (save_pos != use) #endif - *save_pos= *use; - prev=use; - found_eq_constant= !use->used_tables; - /* Save ptr to first use */ - if (!use->table->reginfo.join_tab->keyuse) - use->table->reginfo.join_tab->keyuse=save_pos; - use->table->reginfo.join_tab->checked_keys.set_bit(use->key); - save_pos++; - } - i=(uint) (save_pos-(KEYUSE*) keyuse->buffer); - VOID(set_dynamic(keyuse,(uchar*) &key_end,i)); - keyuse->elements=i; - } - DBUG_EXECUTE("opt", print_keyuse_array(keyuse);); + *save_pos= *use; + prev= use; + found_eq_constant= !use->used_tables; + /* Save ptr to first use */ + if (!use->table->reginfo.join_tab->keyuse) + use->table->reginfo.join_tab->keyuse=save_pos; + use->table->reginfo.join_tab->checked_keys.set_bit(use->key); + save_pos++; + } + i= (uint) (save_pos-(KEYUSE*) keyuse->buffer); + VOID(set_dynamic(keyuse,(uchar*) &key_end,i)); + keyuse->elements= i; + return FALSE; } + /** Update some values in keyuse for faster choose_plan() loop. */ @@ -4572,8 +4582,8 @@ best_access_path(JOIN *join, if (!(keyuse->used_tables & ~join->const_table_map)) const_part|= keyuse->keypart_map; - double tmp2= prev_record_reads(join, idx, (found_ref | - keyuse->used_tables)); + double tmp2= prev_record_reads(join->positions, idx, + (found_ref | keyuse->used_tables)); if (tmp2 < best_prev_record_reads) { best_part_found_ref= keyuse->used_tables & ~join->const_table_map; @@ -4613,7 +4623,7 @@ best_access_path(JOIN *join, Really, there should be records=0.0 (yes!) but 1.0 would be probably safer */ - tmp= prev_record_reads(join, idx, found_ref); + tmp= prev_record_reads(join->positions, idx, found_ref); records= 1.0; } else @@ -4628,7 +4638,7 @@ best_access_path(JOIN *join, max_key_part= (uint) ~0; if ((keyinfo->flags & (HA_NOSAME | HA_NULL_PART_KEY)) == HA_NOSAME) { - tmp = prev_record_reads(join, idx, found_ref); + tmp = prev_record_reads(join->positions, idx, found_ref); records=1.0; } else @@ -5342,6 +5352,7 @@ optimize_straight_join(JOIN *join, table_map join_tables) read_time+= record_count; // We have to make a temp table memcpy((uchar*) join->best_positions, (uchar*) join->positions, sizeof(POSITION)*idx); + join->record_count= record_count; join->best_read= read_time; } @@ -5523,40 +5534,45 @@ greedy_search(JOIN *join, } -/* - Calculate a cost of given partial join order +/** + Calculate a cost of given partial join order in join->positions. - SYNOPSIS - get_partial_join_cost() - join IN Join to use. join->positions holds the - partial join order - idx IN # tables in the partial join order - read_time_arg OUT Store read time here - record_count_arg OUT Store record count here + @param n_tables[in] # tables in the partial join order after the last + constant table + @param read_time_arg[out] store read time here + @param record_count_arg[out] store record count here - DESCRIPTION - - This is needed for semi-join materialization code. The idea is that - we detect sj-materialization after we've put all sj-inner tables into - the join prefix + @note + When used by semi-join materialization code the idea is that we + detect sj-materialization after we've put all sj-inner tables into + the join prefix. prefix-tables semi-join-inner-tables tN ^--we're here and we'll need to get the cost of prefix-tables prefix again. + + When used with non-flattened subqueries, the method computes the + total cost of query plan. + + @returns + read_time_arg and record_count_arg contain the computed cost. */ -void get_partial_join_cost(JOIN *join, uint n_tables, double *read_time_arg, - double *record_count_arg) +void JOIN::get_partial_join_cost(uint n_tables, + double *read_time_arg, double *record_count_arg) { double record_count= 1; double read_time= 0.0; - for (uint i= join->const_tables; i < n_tables + join->const_tables ; i++) + + DBUG_ASSERT(n_tables <= tables); + + for (uint i= const_tables; i < n_tables; i++) { - if (join->best_positions[i].records_read) + if (best_positions[i].records_read) { - record_count *= join->best_positions[i].records_read; - read_time += join->best_positions[i].read_time; + record_count *= best_positions[i].records_read; + read_time += best_positions[i].read_time; } } *read_time_arg= read_time;// + record_count / TIME_FOR_COMPARE; @@ -5564,8 +5580,6 @@ void get_partial_join_cost(JOIN *join, uint n_tables, double *read_time_arg, } - - /** Find a good, possibly optimal, query execution plan (QEP) by a possibly exhaustive search. @@ -5818,6 +5832,7 @@ best_extension_by_limited_search(JOIN *join, { memcpy((uchar*) join->best_positions, (uchar*) join->positions, sizeof(POSITION) * (idx + 1)); + join->record_count= current_record_count; join->best_read= current_read_time - 0.001; } DBUG_EXECUTE("opt", print_plan(join, idx+1, @@ -6040,7 +6055,7 @@ int JOIN_TAB::make_scan_filter() if (cond && (tmp=make_cond_for_table(cond, join->const_table_map | table->map, - table->map, FALSE, TRUE))) + table->map, MAX_TABLES, FALSE, TRUE))) { DBUG_EXECUTE("where",print_where(tmp,"cache", QT_ORDINARY);); if (!(cache_select= @@ -6121,12 +6136,12 @@ cache_record_length(JOIN *join,uint idx) Expected number of row combinations */ -static double -prev_record_reads(JOIN *join, uint idx, table_map found_ref) +double +prev_record_reads(POSITION *positions, uint idx, table_map found_ref) { double found=1.0; - POSITION *pos_end= join->positions - 1; - for (POSITION *pos= join->positions + idx - 1; pos != pos_end; pos--) + POSITION *pos_end= positions - 1; + for (POSITION *pos= positions + idx - 1; pos != pos_end; pos--) { if (pos->table->table->map & found_ref) { @@ -6823,15 +6838,16 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) there inside the triggers. */ { // Check const tables - COND *const_cond= + join->exec_const_cond= make_cond_for_table(cond, join->const_table_map, - (table_map) 0, TRUE, FALSE); + (table_map) 0, MAX_TABLES, FALSE, FALSE); /* Add conditions added by add_not_null_conds(). */ for (uint i= 0 ; i < join->const_tables ; i++) - add_cond_and_fix(&const_cond, join->join_tab[i].select_cond); + add_cond_and_fix(&join->exec_const_cond, join->join_tab[i].select_cond); - DBUG_EXECUTE("where",print_where(const_cond,"constants", QT_ORDINARY);); + DBUG_EXECUTE("where",print_where(join->exec_const_cond,"constants", + QT_ORDINARY);); for (JOIN_TAB *tab= join->join_tab+join->const_tables; tab < join->join_tab+join->tables ; tab++) { @@ -6840,7 +6856,8 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) JOIN_TAB *cond_tab= tab->first_inner; COND *tmp= make_cond_for_table(*tab->on_expr_ref, join->const_table_map, - (table_map) 0, FALSE, FALSE); + (table_map) 0, MAX_TABLES, + FALSE, FALSE); if (!tmp) continue; tmp= new Item_func_trig_cond(tmp, &cond_tab->not_null_compl); @@ -6856,10 +6873,13 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) cond_tab->select_cond->quick_fix_field(); } } - if (const_cond && !const_cond->val_int()) + + if (join->exec_const_cond && !join->exec_const_cond->is_expensive() && + !join->exec_const_cond->val_int()) { - DBUG_PRINT("info",("Found impossible WHERE condition")); - DBUG_RETURN(1); // Impossible const condition + DBUG_PRINT("info",("Found impossible WHERE condition")); + join->exec_const_cond= NULL; + DBUG_RETURN(1); // Impossible const condition } } } @@ -6929,7 +6949,7 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) tmp= NULL; if (cond) - tmp= make_cond_for_table(cond, used_tables, current_map, FALSE, FALSE); + tmp= make_cond_for_table(cond, used_tables, current_map, i, FALSE, FALSE); /* Add conditions added by add_not_null_conds(). */ if (tab->select_cond) add_cond_and_fix(&tmp, tab->select_cond); @@ -6990,7 +7010,8 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) if (thd->variables.engine_condition_pushdown && !first_inner_tab) { COND *push_cond= - make_cond_for_table(tmp, current_map, current_map, FALSE, FALSE); + make_cond_for_table(tmp, current_map, current_map, MAX_TABLES, + FALSE, FALSE); if (push_cond) { /* Push condition to handler */ @@ -7141,7 +7162,7 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) JOIN_TAB *cond_tab= join_tab->first_inner; COND *tmp= make_cond_for_table(*join_tab->on_expr_ref, join->const_table_map, - (table_map) 0, FALSE, FALSE); + (table_map) 0, MAX_TABLES, FALSE, FALSE); if (!tmp) continue; tmp= new Item_func_trig_cond(tmp, &cond_tab->not_null_compl); @@ -7160,6 +7181,7 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) } /* Push down non-constant conditions from on expressions */ + JOIN_TAB *first_tab= join->join_tab+join->const_tables; JOIN_TAB *last_tab= tab; while (first_inner_tab && first_inner_tab->last_inner == last_tab) { @@ -7171,12 +7193,13 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) table_map used_tables2= (join->const_table_map | OUTER_REF_TABLE_BIT | RAND_TABLE_BIT); - for (tab= join->join_tab+join->const_tables; tab <= last_tab ; tab++) + for (tab= first_tab; tab <= last_tab ; tab++) { current_map= tab->table->map; used_tables2|= current_map; COND *tmp_cond= make_cond_for_table(on_expr, used_tables2, - current_map, FALSE, FALSE); + current_map, (tab - first_tab), + FALSE, FALSE); if (tab == first_inner_tab && tab->on_precond) add_cond_and_fix(&tmp_cond, tab->on_precond); if (tmp_cond) @@ -8628,11 +8651,16 @@ remove_const(JOIN *join,ORDER *first_order, COND *cond, *simple_order=0; // Must do a temp table to sort else if (!(order_tables & not_const_tables)) { - if (order->item[0]->with_subselect && - !(join->select_lex->options & SELECT_DESCRIBE)) - order->item[0]->val_str(&order->item[0]->str_value); + if (order->item[0]->with_subselect) + { + /* + Delay the evaluation of constant ORDER and/or GROUP expressions that + contain subqueries until the execution phase. + */ + join->exec_const_order_group_cond.push_back(order->item[0]); + } DBUG_PRINT("info",("removing: %s", order->item[0]->full_name())); - continue; // skip const item + continue; } else { @@ -11763,10 +11791,30 @@ create_tmp_table(THD *thd,TMP_TABLE_PARAM *param,List<Item> &fields, { if (thd->is_fatal_error) goto err; // Got OOM - continue; // Some kindf of const item + continue; // Some kind of const item } if (type == Item::SUM_FUNC_ITEM) - ((Item_sum *) item)->result_field= new_field; + { + Item_sum *agg_item= (Item_sum *) item; + /* + Update the result field only if it has never been set, or if the + created temporary table is not to be used for subquery + materialization. + + The reason is that for subqueries that require materialization as part + of their plan, we create the 'external' temporary table needed for IN + execution, after the 'internal' temporary table needed for grouping. + Since both the external and the internal temporary tables are created + for the same list of SELECT fields of the subquery, setting + 'result_field' for each invocation of create_tmp_table overrides the + previous value of 'result_field'. + + The condition below prevents the creation of the external temp table + to override the 'result_field' that was set for the internal temp table. + */ + if (!agg_item->result_field || !param->materialized_subquery) + agg_item->result_field= new_field; + } tmp_from_field++; reclength+=new_field->pack_length(); if (!(new_field->flags & NOT_NULL_FLAG)) @@ -14941,7 +14989,6 @@ bool test_if_ref(Item *root_cond, Item_field *left_item,Item *right_item) } - /* Extract a condition that can be checked after reading given table @@ -14951,6 +14998,8 @@ bool test_if_ref(Item *root_cond, Item_field *left_item,Item *right_item) tables Tables for which "current field values" are available used_table Table that we're extracting the condition for (may also include PSEUDO_TABLE_BITS + join_tab_idx_arg The index of the JOIN_TAB this Item is being extracted + for. MAX_TABLES if there is no corresponding JOIN_TAB. exclude_expensive_cond Do not push expensive conditions retain_ref_cond Retain ref conditions @@ -14978,34 +15027,24 @@ bool test_if_ref(Item *root_cond, Item_field *left_item,Item *right_item) static Item * make_cond_for_table(Item *cond, table_map tables, table_map used_table, - bool exclude_expensive_cond, bool retain_ref_cond) + uint join_tab_idx_arg, + bool exclude_expensive_cond __attribute__((unused)), + bool retain_ref_cond) { return make_cond_for_table_from_pred(cond, cond, tables, used_table, + join_tab_idx_arg, exclude_expensive_cond, retain_ref_cond); } - + static Item * make_cond_for_table_from_pred(Item *root_cond, Item *cond, table_map tables, table_map used_table, - bool exclude_expensive_cond, + uint join_tab_idx_arg, + bool exclude_expensive_cond __attribute__((unused)), bool retain_ref_cond) { - if (used_table && !(cond->used_tables() & used_table) && - /* - Exclude constant conditions not checked at optimization time if - the table we are pushing conditions to is the first one. - As a result, such conditions are not considered as already checked - and will be checked at execution time, attached to the first table. - - psergey: TODO: "used_table & 1" doesn't make sense in nearly any - context. Look at setup_table_map(), table bits reflect the order - the tables were encountered by the parser. Check what we should - replace this condition with. - */ - !((used_table & 1) && cond->is_expensive())) - return (COND*) 0; // Already checked if (cond->type() == Item::COND_ITEM) { if (((Item_cond*) cond)->functype() == Item_func::COND_AND_FUNC) @@ -15020,6 +15059,7 @@ make_cond_for_table_from_pred(Item *root_cond, Item *cond, { Item *fix=make_cond_for_table_from_pred(root_cond, item, tables, used_table, + join_tab_idx_arg, exclude_expensive_cond, retain_ref_cond); if (fix) @@ -15053,6 +15093,7 @@ make_cond_for_table_from_pred(Item *root_cond, Item *cond, { Item *fix=make_cond_for_table_from_pred(root_cond, item, tables, 0L, + join_tab_idx_arg, exclude_expensive_cond, retain_ref_cond); if (!fix) @@ -15075,16 +15116,14 @@ make_cond_for_table_from_pred(Item *root_cond, Item *cond, table_count times, we mark each item that we have examined with the result of the test */ - if ((cond->marker == 3 && !retain_ref_cond) || - (cond->used_tables() & ~tables) || - /* - When extracting constant conditions, treat expensive conditions as - non-constant, so that they are not evaluated at optimization time. - */ - (!used_table && exclude_expensive_cond && cond->is_expensive())) + if ((cond->marker == 3 && !retain_ref_cond) || + (cond->used_tables() & ~tables)) return (COND*) 0; // Can't check this yet if (cond->marker == 2 || cond->eq_cmp_result() == Item::COND_OK) + { + cond->set_join_tab_idx(join_tab_idx_arg); return cond; // Not boolean op + } if (cond->type() == Item::FUNC_ITEM && ((Item_func*) cond)->functype() == Item_func::EQ_FUNC) @@ -15105,11 +15144,11 @@ make_cond_for_table_from_pred(Item *root_cond, Item *cond, } } cond->marker=2; + cond->set_join_tab_idx(join_tab_idx_arg); return cond; } - static COND * make_cond_after_sjm(Item *root_cond, Item *cond, table_map tables, table_map sjm_tables) @@ -16285,7 +16324,7 @@ static bool fix_having(JOIN *join, Item **having) DBUG_EXECUTE("where",print_where(*having,"having", QT_ORDINARY);); Item* sort_table_cond=make_cond_for_table(*having, used_tables, used_tables, - FALSE, FALSE); + MAX_TABLES, FALSE, FALSE); if (sort_table_cond) { if (!table->select) @@ -16304,7 +16343,7 @@ static bool fix_having(JOIN *join, Item **having) "select and having", QT_ORDINARY);); *having= make_cond_for_table(*having,~ (table_map) 0,~used_tables, - FALSE, FALSE); + MAX_TABLES, FALSE, FALSE); DBUG_EXECUTE("where", print_where(*having,"having after make_cond", QT_ORDINARY);); } @@ -19238,28 +19277,9 @@ bool mysql_explain_union(THD *thd, SELECT_LEX_UNIT *unit, select_result *result) bool res= 0; SELECT_LEX *first= unit->first_select(); - for (SELECT_LEX *sl= first; - sl; - sl= sl->next_select()) - { - // drop UNCACHEABLE_EXPLAIN, because it is for internal usage only - uint8 uncacheable= (sl->uncacheable & ~UNCACHEABLE_EXPLAIN); - sl->type= (((&thd->lex->select_lex)==sl)? - (sl->first_inner_unit() || sl->next_select() ? - "PRIMARY" : "SIMPLE"): - ((sl == first)? - ((sl->linkage == DERIVED_TABLE_TYPE) ? - "DERIVED": - ((uncacheable & UNCACHEABLE_DEPENDENT) ? - "DEPENDENT SUBQUERY": - (uncacheable?"UNCACHEABLE SUBQUERY": - "SUBQUERY"))): - ((uncacheable & UNCACHEABLE_DEPENDENT) ? - "DEPENDENT UNION": - uncacheable?"UNCACHEABLE UNION": - "UNION"))); - sl->options|= SELECT_DESCRIBE; - } + for (SELECT_LEX *sl= first; sl; sl= sl->next_select()) + sl->set_explain_type(); + if (unit->is_union()) { unit->fake_select_lex->select_number= UINT_MAX; // jost for initialization @@ -19675,6 +19695,8 @@ bool JOIN::change_result(select_result *res) { DBUG_ENTER("JOIN::change_result"); result= res; + if (tmp_join) + tmp_join->result= res; if (!procedure && (result->prepare(fields_list, select_lex->master_unit()) || result->prepare2())) { @@ -19683,6 +19705,143 @@ bool JOIN::change_result(select_result *res) DBUG_RETURN(FALSE); } + +/** + Save a query execution plan so that the caller can revert to it if needed, + and reset the current query plan so that it can be reoptimized. + + @param save_to The object into which the current query plan state is saved +*/ + +void JOIN::save_query_plan(Query_plan_state *save_to) +{ + if (keyuse.elements) + { + DYNAMIC_ARRAY tmp_keyuse; + // TODO: isn't this allocated by update_ref_and_keys + //if (my_init_dynamic_array(save_keyuse, sizeof(KEYUSE), 20, 64)) + // return 1; + /* Swap the current and the backup keyuse arrays. */ + tmp_keyuse= keyuse; + keyuse= save_to->keyuse; + save_to->keyuse= tmp_keyuse; + + for (uint i= 0; i < tables; i++) + { + save_to->join_tab_keyuse[i]= join_tab[i].keyuse; + join_tab[i].keyuse= NULL; + save_to->join_tab_checked_keys[i]= join_tab[i].checked_keys; + join_tab[i].checked_keys.clear_all(); + } + } + memcpy((uchar*) save_to->best_positions, (uchar*) best_positions, + sizeof(POSITION) * (tables + 1)); + memset(best_positions, 0, sizeof(POSITION) * (tables + 1)); +} + + +/** + Restore a query execution plan previously saved by the caller. + + @param The object from which the current query plan state is restored. +*/ + +void JOIN::restore_query_plan(Query_plan_state *restore_from) +{ + if (restore_from->keyuse.elements) + { + DYNAMIC_ARRAY tmp_keyuse; + tmp_keyuse= keyuse; + keyuse= restore_from->keyuse; + restore_from->keyuse= tmp_keyuse; + + for (uint i= 0; i < tables; i++) + { + join_tab[i].keyuse= restore_from->join_tab_keyuse[i]; + join_tab[i].checked_keys= restore_from->join_tab_checked_keys[i]; + } + + } + memcpy((uchar*) best_positions, (uchar*) restore_from->best_positions, + sizeof(POSITION) * (tables + 1)); +} + + +/** + Reoptimize a query plan taking into account an additional conjunct to the + WHERE clause. + + @param added_where An extra conjunct to the WHERE clause to reoptimize with + @param join_tables The set of tables to reoptimize + @param save_to If != NULL, save here the state of the current query plan + + @notes + Given a query plan that already optimized taking into account some WHERE clause + 'C', reoptimize this plan with a new WHERE clause 'C AND added_where'. The + reoptimization works as follows: + + 1. Call update_ref_and_keys *only* for the new conditions 'added_where' + that are about to be injected into the query. + 2. Expand if necessary the original KEYUSE array JOIN::keyuse to + accommodate the new REF accesses computed for the 'added_where' condition. + 3. Add the new KEYUSEs into JOIN::keyuse. + 4. Re-sort and re-filter the JOIN::keyuse array with the newly added + KEYUSE elements. + + @retval REOPT_NEW_PLAN there is a new plan. + @retval REOPT_OLD_PLAN no new improved plan was produced, use the old one. + @retval REOPT_ERROR an irrecovarable error occured during reoptimization. +*/ + +JOIN::enum_reopt_result +JOIN::reoptimize(Item *added_where, table_map join_tables, + Query_plan_state *save_to) +{ + DYNAMIC_ARRAY added_keyuse; + SARGABLE_PARAM *sargables= 0; /* Used only as a dummy parameter. */ + + /* Re-run the REF optimizer to take into account the new conditions. */ + if (update_ref_and_keys(thd, &added_keyuse, join_tab, tables, added_where, + ~outer_join, select_lex, &sargables)) + { + delete_dynamic(&added_keyuse); + return REOPT_ERROR; + } + + if (!added_keyuse.elements) + { + delete_dynamic(&added_keyuse); + return REOPT_OLD_PLAN; + } + + if (save_to) + save_query_plan(save_to); + + /* Add the new access methods to the keyuse array. */ + if (!keyuse.buffer && + my_init_dynamic_array(&keyuse, sizeof(KEYUSE), 20, 64)) + { + delete_dynamic(&added_keyuse); + return REOPT_ERROR; + } + allocate_dynamic(&keyuse, keyuse.elements + added_keyuse.elements); + memcpy(keyuse.buffer + keyuse.elements * keyuse.size_of_element, + added_keyuse.buffer, + (size_t) added_keyuse.elements * added_keyuse.size_of_element); + keyuse.elements+= added_keyuse.elements; + delete_dynamic(&added_keyuse); + + if (sort_and_filter_keyuse(&keyuse)) + return REOPT_ERROR; + optimize_keyuse(this, &keyuse); + + /* Re-run the join optimizer to compute a new query plan. */ + if (choose_plan(this, join_tables)) + return REOPT_ERROR; + + return REOPT_NEW_PLAN; +} + /** @} (end of group Query_Optimizer) */ diff --git a/sql/sql_select.h b/sql/sql_select.h index ecc19f763fa..7b3099fcf2d 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -568,8 +568,53 @@ inline bool sj_is_materialize_strategy(uint strategy) class JOIN :public Sql_alloc { +private: JOIN(const JOIN &rhs); /**< not implemented */ JOIN& operator=(const JOIN &rhs); /**< not implemented */ + +protected: + + /** + The subset of the state of a JOIN that represents an optimized query + execution plan. Allows saving/restoring different plans for the same query. + */ + class Query_plan_state { + public: + DYNAMIC_ARRAY keyuse; /* Copy of the JOIN::keyuse array. */ + POSITION best_positions[MAX_TABLES+1]; /* Copy of JOIN::best_positions */ + /* Copies of the JOIN_TAB::keyuse pointers for each JOIN_TAB. */ + KEYUSE *join_tab_keyuse[MAX_TABLES]; + /* Copies of JOIN_TAB::checked_keys for each JOIN_TAB. */ + key_map join_tab_checked_keys[MAX_TABLES]; + public: + Query_plan_state() + { + keyuse.elements= 0; + keyuse.buffer= NULL; + } + Query_plan_state(JOIN *join); + ~Query_plan_state() + { + delete_dynamic(&keyuse); + } + }; + + /* Results of reoptimizing a JOIN via JOIN::reoptimize(). */ + enum enum_reopt_result { + REOPT_NEW_PLAN, /* there is a new reoptimized plan */ + REOPT_OLD_PLAN, /* no new improved plan can be found, use the old one */ + REOPT_ERROR, /* an irrecovarable error occured during reoptimization */ + REOPT_NONE /* not yet reoptimized */ + }; + + /* Support for plan reoptimization with rewritten conditions. */ + enum_reopt_result reoptimize(Item *added_where, table_map join_tables, + Query_plan_state *save_to); + void save_query_plan(Query_plan_state *save_to); + void restore_query_plan(Query_plan_state *restore_from); + /* Choose a subquery plan for a table-less subquery. */ + bool choose_tableless_subquery_plan(); + public: JOIN_TAB *join_tab,**best_ref; JOIN_TAB **map2table; ///< mapping between table indexes and JOIN_TABs @@ -667,6 +712,13 @@ public: account the changes made by test_if_skip_sort_order()). */ double best_read; + /* + Estimated result rows (fanout) of the whole query. If this is a subquery + that is reexecuted multiple times, this value includes the estiamted # of + reexecutions. This value is equal to the multiplication of all + join->positions[i].records_read of a JOIN. + */ + double record_count; List<Item> *fields; List<Cached_item> group_fields, group_fields_cache; TABLE *tmp_table; @@ -770,6 +822,19 @@ public: List<TABLE_LIST> *join_list; ///< list of joined tables in reverse order COND_EQUAL *cond_equal; COND_EQUAL *having_equal; + /* + Constant codition computed during optimization, but evaluated during + join execution. Typically expensive conditions that should not be + evaluated at optimization time. + */ + Item *exec_const_cond; + /* + Constant ORDER and/or GROUP expressions that contain subqueries. Such + expressions need to evaluated to verify that the subquery indeed + returns a single row. The evaluation of such expressions is delayed + until query execution. + */ + List<Item> exec_const_order_group_cond; SQL_SELECT *select; ///<created in optimisation phase JOIN_TAB *return_tab; ///<used only for outer joins Item **ref_pointer_array; ///<used pointer reference for this select @@ -780,8 +845,15 @@ public: bool union_part; ///< this subselect is part of union bool optimized; ///< flag to avoid double optimization in EXPLAIN + bool initialized; ///< flag to avoid double init_execution calls Array<Item_in_subselect> sj_subselects; + /* + Additional WHERE and HAVING predicates to be considered for IN=>EXISTS + subquery transformation of a JOIN object. + */ + Item *in_to_exists_where; + Item *in_to_exists_having; /* Temporary tables used to weed-out semi-join duplicates */ List<TABLE> sj_tmp_tables; @@ -856,8 +928,10 @@ public: ref_pointer_array_size= 0; zero_result_cause= 0; optimized= 0; + initialized= 0; cond_equal= 0; having_equal= 0; + exec_const_cond= 0; group_optimized_away= 0; no_rows_in_result_called= 0; @@ -871,6 +945,8 @@ public: no_const_tables= FALSE; first_select= sub_select; + in_to_exists_where= NULL; + in_to_exists_having= NULL; } int prepare(Item ***rref_pointer_array, TABLE_LIST *tables, uint wind_num, @@ -879,12 +955,13 @@ public: SELECT_LEX_UNIT *unit); int optimize(); int reinit(); + int init_execution(); void exec(); int destroy(); void restore_tmp(); bool alloc_func_list(); bool flatten_subqueries(); - bool setup_subquery_materialization(); + bool optimize_unflattened_subqueries(); bool make_sum_func_list(List<Item> &all_fields, List<Item> &send_fields, bool before_group_by, bool recompute= FALSE); @@ -921,7 +998,8 @@ public: bool send_row_on_empty_set() { return (do_send_rows && tmp_table_param.sum_func_count != 0 && - !group_list && having_value != Item::COND_FALSE); + !(group_list || group_optimized_away) && + having_value != Item::COND_FALSE); } bool change_result(select_result *result); bool is_top_level_join() const @@ -947,6 +1025,9 @@ public: bool shrink_join_buffers(JOIN_TAB *jt, ulonglong curr_space, ulonglong needed_space); + bool choose_subquery_plan(table_map join_tables); + void get_partial_join_cost(uint n_tables, + double *read_time_arg, double *record_count_arg); private: /** @@ -1167,6 +1248,9 @@ protected: if (!inited) { inited=1; + TABLE *table= to_field->table; + my_bitmap_map *old_map= dbug_tmp_use_all_columns(table, + table->write_set); if ((res= item->save_in_field(to_field, 1))) { if (!err) @@ -1178,6 +1262,7 @@ protected: */ if (!err && to_field->table->in_use->is_error()) err= 1; /* STORE_KEY_FATAL */ + dbug_tmp_restore_column_map(table->write_set, old_map); } null_key= to_field->is_null() || item->null_value; return (err > 2 ? STORE_KEY_FATAL : (store_key_result) err); @@ -1196,9 +1281,7 @@ inline Item * and_items(Item* cond, Item *item) { return (cond? (new Item_cond_and(cond, item)) : item); } -bool choose_plan(JOIN *join,table_map join_tables); -void get_partial_join_cost(JOIN *join, uint n_tables, double *read_time_arg, - double *record_count_arg); +bool choose_plan(JOIN *join, table_map join_tables); void optimize_wo_join_buffering(JOIN *join, uint first_tab, uint last_tab, table_map last_remaining_tables, bool first_alt, uint no_jbuf_before, @@ -1244,5 +1327,6 @@ bool create_internal_tmp_table(TABLE *table, KEY *keyinfo, ulonglong options); bool open_tmp_table(TABLE *table); void setup_tmp_table_column_bitmaps(TABLE *table, uchar *bitmaps); +double prev_record_reads(POSITION *positions, uint idx, table_map found_ref); #endif /* SQL_SELECT_INCLUDED */ diff --git a/sql/sql_union.cc b/sql/sql_union.cc index a94ad9f3b4b..4a6c37f5f80 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -184,6 +184,8 @@ st_select_lex_unit::init_prepare_fake_select_lex(THD *thd_arg) { (*order->item)->walk(&Item::change_context_processor, 0, (uchar*) &fake_select_lex->context); + (*order->item)->walk(&Item::set_fake_select_as_master_processor, 0, + (uchar*) fake_select_lex); } } @@ -268,6 +270,18 @@ bool st_select_lex_unit::prepare(THD *thd_arg, select_result *sel_result, can_skip_order_by= is_union_select && !(sl->braces && sl->explicit_limit); + /* + Remove all references from the select_lex_units to the subqueries that + are inside the ORDER BY clause. + */ + if (can_skip_order_by) + { + for (ORDER *ord= (ORDER *)sl->order_list.first; ord; ord= ord->next) + { + (*ord->item)->walk(&Item::eliminate_subselect_processor, FALSE, NULL); + } + } + saved_error= join->prepare(&sl->ref_pointer_array, sl->table_list.first, sl->with_wild, diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 6a4027318d5..b37c3747de6 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -307,6 +307,10 @@ int mysql_update(THD *thd, DBUG_RETURN(1); /* purecov: inspected */ } + /* Apply the IN=>EXISTS transformation to all subqueries and optimize them. */ + if (select_lex->optimize_unflattened_subqueries()) + DBUG_RETURN(TRUE); + if (select_lex->inner_refs_list.elements && fix_inner_refs(thd, all_fields, select_lex, select_lex->ref_pointer_array)) DBUG_RETURN(1); |