diff --git a/mysql-test/main/insert_select.result b/mysql-test/main/insert_select.result index 29618c6ddd4..463f571b096 100644 --- a/mysql-test/main/insert_select.result +++ b/mysql-test/main/insert_select.result @@ -973,7 +973,6 @@ select * from t1; a 3 1 -2 delete from t1; insert into t1 values (3), (1); insert into t1 @@ -984,8 +983,6 @@ select * from t1; a 3 1 -3 -2 delete from t1; insert into t1 values (3), (1); insert into t1 @@ -996,6 +993,7 @@ select * from t1; a 3 1 +3 2 delete from t1; insert into t1 values (3), (1); @@ -1022,7 +1020,6 @@ select * from t1; a 3 1 -2 delete from t1; insert into t1 values (3), (1); execute stmt; @@ -1030,7 +1027,6 @@ select * from t1; a 3 1 -2 delete from t1; insert into t1 values (3), (1); delete from t1 @@ -1040,6 +1036,8 @@ group by (select * from (select a from t1) dt where a = 1))); select * from t1; a +3 +1 deallocate prepare stmt; drop table t1,t2,t3; # diff --git a/mysql-test/main/subselect4.result b/mysql-test/main/subselect4.result index b29a26d8ac5..7bf2f3bf373 100644 --- a/mysql-test/main/subselect4.result +++ b/mysql-test/main/subselect4.result @@ -2979,34 +2979,31 @@ where a >= any (select b from t2 group by (select c from t3 where c = 1)); 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 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00 +3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) <= (`test`.`t1`.`a`))) +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select `test`.`t2`.`b` from `test`.`t2` group by (/* select#3 */ select `test`.`t3`.`c` from `test`.`t3` where `test`.`t3`.`c` = 1)) <= (`test`.`t1`.`a`))) select a from t1 where a >= any (select b from t2 group by (select c from t3 where c = 1)); a -3 -2 prepare stmt from "select a from t1 where a >= any (select b from t2 group by (select c from t3 where c = 1))"; execute stmt; a -3 -2 execute stmt; a -3 -2 deallocate prepare stmt; explain extended select a from t1 where a <= all (select b from t2 group by (select c from t3 where c = 1)); 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 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00 +3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) < (`test`.`t1`.`a`))) +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select `test`.`t2`.`b` from `test`.`t2` group by (/* select#3 */ select `test`.`t3`.`c` from `test`.`t3` where `test`.`t3`.`c` = 1)) < (`test`.`t1`.`a`))) select a from t1 where a <= all (select b from t2 group by (select c from t3 where c = 1)); a +3 1 2 explain extended select a from t1 @@ -3014,13 +3011,12 @@ where a >= any (select b from t2 group by 1 + (select c from t3 where c = 1)); 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 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00 +3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) <= (`test`.`t1`.`a`))) +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((`test`.`t1`.`a`,(/* select#2 */ select `test`.`t2`.`b` from `test`.`t2` group by 1 + (/* select#3 */ select `test`.`t3`.`c` from `test`.`t3` where `test`.`t3`.`c` = 1)) <= (`test`.`t1`.`a`))) select a from t1 where a >= any (select b from t2 group by 1 + (select c from t3 where c = 1)); a -3 -2 drop table t1,t2,t3; # # MDEV-29139: Redundant IN/ALL/ANY predicand in GROUP BY clause of @@ -3040,8 +3036,10 @@ group by (select a from t1 where a = 1) in (select d from t4)); id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1 +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where (1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by ((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) = `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null))) limit 1)) select b from t2 where exists (select c from t3 group by (select a from t1 where a = 1) in (select d from t4)); @@ -3067,8 +3065,10 @@ any (select d from t4)); id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1 +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where (1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by (<(/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)>(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) >= `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null))))) limit 1)) select b from t2 where exists (select c from t3 group by (select a from t1 where a = 1) >= @@ -3083,8 +3083,10 @@ all (select d from t4)); id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1 +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where (1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by (<(/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)>(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) >= `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null))))) limit 1)) select b from t2 where exists (select c from t3 group by (select a from t1 where a = 1) < @@ -3096,16 +3098,17 @@ explain extended select b from t2 where b in (select c from t3 group by (select a from t1 where a = 1) in (select d from t4)); id select_type table type possible_keys key key_len ref rows filtered Extra -1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 -1 PRIMARY eq_ref distinct_key distinct_key 4 func 1 100.00 +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where +1 PRIMARY eq_ref distinct_key distinct_key 4 test.t2.b 1 100.00 2 MATERIALIZED t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 select `test`.`t2`.`b` AS `b` from `test`.`t2` semi join (`test`.`t3`) where 1 +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from (/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by ((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) = `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null)))) join `test`.`t2` where ``.`c` = `test`.`t2`.`b` select b from t2 where b in (select c from t3 group by (select a from t1 where a = 1) in (select d from t4)); b -2 explain extended select b from t2 where b >= any (select c from t3 group by (select a from t1 where a = 1) in @@ -3113,30 +3116,33 @@ group by (select a from t1 where a = 1) in id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where 2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where Warnings: -Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b`,(/* select#2 */ select min(`test`.`t3`.`c`) from `test`.`t3`) <= (`test`.`t2`.`b`))) +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b`,(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by ((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) = `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null)))) <= (`test`.`t2`.`b`))) select b from t2 where b >= any (select c from t3 group by (select a from t1 where a = 1) in (select d from t4)); b +explain extended select b from t2 +where b <= all (select c from t3 +group by (select a from t1 where a = 1) in +(select d from t4)); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where +2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 +4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where +3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b`,(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by ((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)) = `test`.`t4`.`d` or `test`.`t4`.`d` is null) having trigcond(`test`.`t4`.`d` is null)))) < (`test`.`t2`.`b`))) +select b from t2 +where b <= all (select c from t3 +group by (select a from t1 where a = 1) in +(select d from t4)); +b 3 2 -explain extended select b from t2 -where b <= all (select c from t3 -group by (select a from t1 where a = 1) in -(select d from t4)); -id select_type table type possible_keys key key_len ref rows filtered Extra -1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where -2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 -Warnings: -Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where ((`test`.`t2`.`b`,(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3`) < (`test`.`t2`.`b`))) -select b from t2 -where b <= all (select c from t3 -group by (select a from t1 where a = 1) in -(select d from t4)); -b -2 drop table t1,t2,t3,t4; # End of 10.3 tests # diff --git a/mysql-test/main/subselect_elimination.result b/mysql-test/main/subselect_elimination.result new file mode 100644 index 00000000000..17400e490bc --- /dev/null +++ b/mysql-test/main/subselect_elimination.result @@ -0,0 +1,268 @@ +# +# MDEV-28621 group by optimization incorrectly removing subquery where +# subject buried in a function +# +CREATE TABLE t1 (i int) ; +INSERT INTO t1 VALUES (1),(2),(3); +SELECT 1 FROM t1 +WHERE i in +( SELECT a+1 +FROM +(SELECT (SELECT i FROM (SELECT 1 FROM t1) dt) AS a FROM t1) dt2 +GROUP BY a +); +ERROR 21000: Subquery returns more than 1 row +DROP TABLE t1; +create table t1 (a int, b int, c int); +insert into t1 select seq, seq, seq from seq_1_to_10; +create table t2 as select * from t1; +create table t20 as select * from t1; +create table t21 as select * from t1; +create table t3 as select * from t1; +select a, a in +( +select +( +select max(c) from t20 where t20.a<=t2.a +) as SUBQ1 from t2 group by SUBQ1+1 +) as COL +from t1; +a COL +1 1 +2 1 +3 1 +4 1 +5 1 +6 1 +7 1 +8 1 +9 1 +10 1 +create view v2 as +select +a, b, +(select max(c) from t20 where t20.a<=t2.a) as SUBQ1, +(select max(c) from t21 where t21.a<=t2.a) as SUBQ2 +from t2; +# test partial elimination +explain +select +a, +a in (select a from v2 where a>3 and v2.SUBQ2>=0 group by v2.SUBQ1, v2.SUBQ2) +from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +5 DEPENDENT SUBQUERY t21 ALL NULL NULL NULL NULL 10 Using where +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +# test buried subselects in group by clause +select a, a in +( +select +( +select max(c) from t20 where t20.a<=t2.a +)*2 as SUBQ1 from t2 group by SUBQ1+1 +) as COL +from t1; +a COL +1 0 +2 1 +3 0 +4 1 +5 0 +6 1 +7 0 +8 1 +9 0 +10 1 +drop view v2; +drop table t1, t2, t20, t21, t3; +# Testcase from MDEV-32311 +SELECT ( +( WITH x ( x ) AS +(SELECT ( SELECT 'x' UNION SELECT 'x' ) FROM ( SELECT ( 'x' ) ) x) +SELECT x FROM x +WHERE x IN ( ( SELECT 'x' AND x GROUP BY x ) ) +) +) AS SUBQ; +SUBQ +x +# MDEV-32390: +CREATE TABLE t0 ( c43 DECIMAL ( 31 ) DEFAULT ( 45 ) ) ; +INSERT INTO t0 VALUES ( 13 ) , ( 29 ) ; +ALTER TABLE t0 ADD COLUMN c24 INT AFTER c43 ; +INSERT INTO t0 VALUES ( DEFAULT , DEFAULT ) , ( DEFAULT , DEFAULT ) ; +SELECT t1 . c22 AS c9 FROM ( SELECT ( SELECT + EXISTS ( SELECT -128 AS c29 ) << +LOCATE ( t0 . c43 , t0 . c24 <= t0 . c24 NOT BETWEEN 4642475734208631537 AND +-108 , NULLIF ( 57 , -8 ) SOUNDS LIKE TRIM( TRAILING FROM 6107036197732405580 ) +) - t0 . c43 AS c57 FROM t0 LIMIT 1 ) AS c22 FROM t0 ) AS t1 HAVING TRIM( CASE +t1 . c22 WHEN -16 THEN RAND ( ) % HEX ( t1 . c22 ) - SUBSTRING_INDEX ( t1 . c22, +':A9SEZxtjN,fKN*zR' , 'V*vhJb}&c%Op,[T[S,j`F9NDsK;\'8 4;m" +P,ce}1r"3ID1DN' ) >> NULLIF ( t1 . c22 , -95 ) ELSE -2 END IS TRUE +FROM t1 . c22 >= EXISTS ( SELECT t2 . c57 AS c59 FROM ( SELECT CASE c24 WHEN +-103 THEN 85 ELSE 22 END IS TRUE AS c57 FROM t0 ) AS t2 WHERE MOD ( 64 , 46 ) = +CONVERT ( 73 , BINARY ) % RAND ( ) IS NOT NULL = -65 GROUP BY c57 , c22 , c22 +WINDOW w0 AS ( PARTITION BY t2 . c57 ) ) & PI ( ) ) ; +c9 +DROP TABLE t0; +# MDEV-32309 +SELECT +( WITH x ( x ) AS +( +WITH x ( x ) AS ( SELECT 1 ) SELECT ( SELECT x ) FROM x +) +SELECT x FROM x WHERE x IN ( SELECT NULL GROUP BY x ) +) as col1 ; +col1 +NULL +# MDEV-32391 +CREATE TABLE t0 ( c15 INT , c33 INT ) engine=innodb; +INSERT INTO t0 ( c15 ) WITH t1 AS ( SELECT SQRT ( 123 ) NOT +REGEXP MOD ( 91 , -121 ) = ALL ( SELECT c15 AS c33 FROM t0 ) AS c49 FROM t0 ) +SELECT t1 . c49 IS UNKNOWN AS c59 FROM t1 CROSS JOIN t0 AS t2 +WHERE t1 . c49 = + EXISTS ( SELECT -5839312620871436105 AS c17 GROUP BY c49 ) +BETWEEN -109 AND CHAR_LENGTH ( 2694839150676403988 ) - - LOWER ( -13 ) ; +DROP TABLE t0; +# MDEV-28620 +CREATE TABLE t1 ( a int); +INSERT INTO t1 VALUES (1),(2); +SELECT EXISTS +( SELECT 1 FROM t1 GROUP BY 1 IN (SELECT a FROM t1) +ORDER BY a + (SELECT 1 FROM t1 WHERE (1,2) NOT IN (SELECT 1,0)) +) as SUBQ; +ERROR 21000: Subquery returns more than 1 row +DROP TABLE t1; +# MDEV-30842 Item_subselect::get_cache_parameters and UBSAN member +# access within null pointer +CREATE TABLE x (x INT) ENGINE=InnoDB; +INSERT INTO x (x) VALUES (0); +INSERT INTO x (x) VALUES (x IN (SELECT (SELECT x FROM (SELECT x FROM +(SELECT 0 IN (SELECT x=0 FROM (SELECT x FROM (SELECT (SELECT (SELECT (SELECT +(SELECT 0 AS x) FROM x AS x) IN (SELECT 0 AS x) AS x) FROM x AS x) IN +(SELECT x WHERE x=0) AS x FROM x AS x) AS x) AS x GROUP BY x) AS x FROM x) AS x) +AS x) IN (SELECT 0 AS x) AS x FROM x)); +ERROR HY000: Table 'x' is specified twice, both as a target for 'INSERT' and as a separate source for data +DROP TABLE x; +# MDEV-28622: Item_subselect eliminated flag set but Item still +# evaluated/used. +CREATE TABLE t1 ( a int) ; +CREATE VIEW v1 (i) AS SELECT EXISTS(SELECT 1) FROM t1; +SELECT 1 FROM v1 WHERE i NOT IN (SELECT i = 0 FROM v1 WHERE i = -1 GROUP BY i); +1 +DROP TABLE t1; +DROP VIEW v1; +CREATE TABLE t(c1 INT); +SELECT 0 +WHERE 0 IN +( +SELECT 0 FROM +( +SELECT 0 IN +( +SELECT +( +SELECT c1 FROM t +) +) AS c +FROM t +) AS dt +WHERE c GROUP BY c +); +0 +DROP TABLE t; +create table t1 (a int, b int, c int); +insert into t1 select seq, seq, seq from seq_1_to_10; +create table t2 as select * from t1; +create table t20 as select * from t1; +create table t3 as select * from t1; +create view v2 as +select +a, b, (select max(c) from t20 where t20.a<=t2.a) as SUBQ1 +from t2; +explain +select +a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +prepare s from ' +explain +select + a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1'; +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +prepare s from ' +explain +select + a, a in (select a from v2 where a>3 and SUBQ1+1 group by v2.SUBQ1) +from t1'; +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +execute s; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +create procedure p1() +begin +explain +select +a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1; +end// +create procedure p2() +begin +explain +select +a, a in (select a from v2 where a>3 and SUBQ1+1 group by v2.SUBQ1) +from t1; +end// +call p1(); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +call p1(); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +call p2(); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +call p2(); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 10 +2 MATERIALIZED t2 ALL NULL NULL NULL NULL 10 Using where; Using temporary +4 DEPENDENT SUBQUERY t20 ALL NULL NULL NULL NULL 10 Using where +drop procedure p1; +drop procedure p2; +drop view v2; +drop table t1,t2,t3,t20; +# end of 10.4 tests diff --git a/mysql-test/main/subselect_elimination.test b/mysql-test/main/subselect_elimination.test new file mode 100644 index 00000000000..9d973477b28 --- /dev/null +++ b/mysql-test/main/subselect_elimination.test @@ -0,0 +1,242 @@ +--source include/have_innodb.inc +--source include/have_sequence.inc + +--echo # +--echo # MDEV-28621 group by optimization incorrectly removing subquery where +--echo # subject buried in a function +--echo # + +CREATE TABLE t1 (i int) ; +INSERT INTO t1 VALUES (1),(2),(3); + +--error ER_SUBQUERY_NO_1_ROW +SELECT 1 FROM t1 +WHERE i in +( SELECT a+1 + FROM + (SELECT (SELECT i FROM (SELECT 1 FROM t1) dt) AS a FROM t1) dt2 + GROUP BY a +); + +DROP TABLE t1; + +create table t1 (a int, b int, c int); +insert into t1 select seq, seq, seq from seq_1_to_10; +create table t2 as select * from t1; +create table t20 as select * from t1; +create table t21 as select * from t1; +create table t3 as select * from t1; +select a, a in +( + select + ( + select max(c) from t20 where t20.a<=t2.a + ) as SUBQ1 from t2 group by SUBQ1+1 +) as COL +from t1; + +create view v2 as +select + a, b, + (select max(c) from t20 where t20.a<=t2.a) as SUBQ1, + (select max(c) from t21 where t21.a<=t2.a) as SUBQ2 +from t2; + +--echo # test partial elimination + +explain +select + a, + a in (select a from v2 where a>3 and v2.SUBQ2>=0 group by v2.SUBQ1, v2.SUBQ2) +from t1; + +--echo # test buried subselects in group by clause + +select a, a in +( + select + ( + select max(c) from t20 where t20.a<=t2.a + )*2 as SUBQ1 from t2 group by SUBQ1+1 +) as COL +from t1; + +drop view v2; +drop table t1, t2, t20, t21, t3; + +--echo # Testcase from MDEV-32311 + +# some warning duplicated using ps-protocol +--disable_warnings +SELECT ( + ( WITH x ( x ) AS + (SELECT ( SELECT 'x' UNION SELECT 'x' ) FROM ( SELECT ( 'x' ) ) x) + SELECT x FROM x + WHERE x IN ( ( SELECT 'x' AND x GROUP BY x ) ) + ) +) AS SUBQ; +--enable_warnings + +--echo # MDEV-32390: + +CREATE TABLE t0 ( c43 DECIMAL ( 31 ) DEFAULT ( 45 ) ) ; +INSERT INTO t0 VALUES ( 13 ) , ( 29 ) ; +ALTER TABLE t0 ADD COLUMN c24 INT AFTER c43 ; +INSERT INTO t0 VALUES ( DEFAULT , DEFAULT ) , ( DEFAULT , DEFAULT ) ; +SELECT t1 . c22 AS c9 FROM ( SELECT ( SELECT + EXISTS ( SELECT -128 AS c29 ) << +LOCATE ( t0 . c43 , t0 . c24 <= t0 . c24 NOT BETWEEN 4642475734208631537 AND +-108 , NULLIF ( 57 , -8 ) SOUNDS LIKE TRIM( TRAILING FROM 6107036197732405580 ) +) - t0 . c43 AS c57 FROM t0 LIMIT 1 ) AS c22 FROM t0 ) AS t1 HAVING TRIM( CASE +t1 . c22 WHEN -16 THEN RAND ( ) % HEX ( t1 . c22 ) - SUBSTRING_INDEX ( t1 . c22, +':A9SEZxtjN,fKN*zR' , 'V*vhJb}&c%Op,[T[S,j`F9NDsK;\'8 4;m" +P,ce}1r"3ID1DN' ) >> NULLIF ( t1 . c22 , -95 ) ELSE -2 END IS TRUE +FROM t1 . c22 >= EXISTS ( SELECT t2 . c57 AS c59 FROM ( SELECT CASE c24 WHEN +-103 THEN 85 ELSE 22 END IS TRUE AS c57 FROM t0 ) AS t2 WHERE MOD ( 64 , 46 ) = +CONVERT ( 73 , BINARY ) % RAND ( ) IS NOT NULL = -65 GROUP BY c57 , c22 , c22 +WINDOW w0 AS ( PARTITION BY t2 . c57 ) ) & PI ( ) ) ; + +DROP TABLE t0; + +--echo # MDEV-32309 + +SELECT + ( WITH x ( x ) AS + ( + WITH x ( x ) AS ( SELECT 1 ) SELECT ( SELECT x ) FROM x + ) + SELECT x FROM x WHERE x IN ( SELECT NULL GROUP BY x ) +) as col1 ; + +--echo # MDEV-32391 + +CREATE TABLE t0 ( c15 INT , c33 INT ) engine=innodb; +INSERT INTO t0 ( c15 ) WITH t1 AS ( SELECT SQRT ( 123 ) NOT +REGEXP MOD ( 91 , -121 ) = ALL ( SELECT c15 AS c33 FROM t0 ) AS c49 FROM t0 ) +SELECT t1 . c49 IS UNKNOWN AS c59 FROM t1 CROSS JOIN t0 AS t2 +WHERE t1 . c49 = + EXISTS ( SELECT -5839312620871436105 AS c17 GROUP BY c49 ) +BETWEEN -109 AND CHAR_LENGTH ( 2694839150676403988 ) - - LOWER ( -13 ) ; +DROP TABLE t0; + +--echo # MDEV-28620 +CREATE TABLE t1 ( a int); +INSERT INTO t1 VALUES (1),(2); + +--error ER_SUBQUERY_NO_1_ROW +SELECT EXISTS +( SELECT 1 FROM t1 GROUP BY 1 IN (SELECT a FROM t1) + ORDER BY a + (SELECT 1 FROM t1 WHERE (1,2) NOT IN (SELECT 1,0)) +) as SUBQ; +DROP TABLE t1; + +--echo # MDEV-30842 Item_subselect::get_cache_parameters and UBSAN member +--echo # access within null pointer + +CREATE TABLE x (x INT) ENGINE=InnoDB; +INSERT INTO x (x) VALUES (0); +--error ER_UPDATE_TABLE_USED +INSERT INTO x (x) VALUES (x IN (SELECT (SELECT x FROM (SELECT x FROM +(SELECT 0 IN (SELECT x=0 FROM (SELECT x FROM (SELECT (SELECT (SELECT (SELECT +(SELECT 0 AS x) FROM x AS x) IN (SELECT 0 AS x) AS x) FROM x AS x) IN +(SELECT x WHERE x=0) AS x FROM x AS x) AS x) AS x GROUP BY x) AS x FROM x) AS x) +AS x) IN (SELECT 0 AS x) AS x FROM x)); +DROP TABLE x; + +--echo # MDEV-28622: Item_subselect eliminated flag set but Item still +--echo # evaluated/used. + +CREATE TABLE t1 ( a int) ; +CREATE VIEW v1 (i) AS SELECT EXISTS(SELECT 1) FROM t1; + +SELECT 1 FROM v1 WHERE i NOT IN (SELECT i = 0 FROM v1 WHERE i = -1 GROUP BY i); +DROP TABLE t1; +DROP VIEW v1; + +CREATE TABLE t(c1 INT); + +SELECT 0 +WHERE 0 IN +( + SELECT 0 FROM + ( + SELECT 0 IN + ( + SELECT + ( + SELECT c1 FROM t + ) + ) AS c + FROM t + ) AS dt + WHERE c GROUP BY c +); + +DROP TABLE t; + +create table t1 (a int, b int, c int); +insert into t1 select seq, seq, seq from seq_1_to_10; +create table t2 as select * from t1; +create table t20 as select * from t1; +create table t3 as select * from t1; + +create view v2 as +select + a, b, (select max(c) from t20 where t20.a<=t2.a) as SUBQ1 +from t2; + +explain +select + a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1; + +prepare s from ' +explain +select + a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1'; + +execute s; +execute s; +execute s; + +prepare s from ' +explain +select + a, a in (select a from v2 where a>3 and SUBQ1+1 group by v2.SUBQ1) +from t1'; + +execute s; +execute s; +execute s; + +delimiter //; + +create procedure p1() +begin +explain +select + a, a in (select a from v2 where a>3 group by v2.SUBQ1) +from t1; +end// + +create procedure p2() +begin +explain +select + a, a in (select a from v2 where a>3 and SUBQ1+1 group by v2.SUBQ1) +from t1; +end// + +delimiter ;// + +call p1(); +call p1(); +call p2(); +call p2(); +drop procedure p1; +drop procedure p2; + + +drop view v2; +drop table t1,t2,t3,t20; + +--echo # end of 10.4 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 54251e2d3ad..215a7113b71 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -671,37 +671,57 @@ void remove_redundant_subquery_clauses(st_select_lex *subq_select_lex) if (subq_select_lex->group_list.elements && !subq_select_lex->with_sum_func && !subq_select_lex->join->having) { + /* + Temporary workaround for MDEV-28621: Do not remove GROUP BY expression + if it has any subqueries in it. + */ + bool have_subquery= false; for (ORDER *ord= subq_select_lex->group_list.first; ord; ord= ord->next) { - /* - Do not remove the item if it is used in select list and then referred - from GROUP BY clause by its name or number. Example: - - select (select ... ) as SUBQ ... group by SUBQ - - Here SUBQ cannot be removed. - */ - if (!ord->in_field_list) + if ((*ord->item)->with_subquery()) { - (*ord->item)->walk(&Item::eliminate_subselect_processor, FALSE, NULL); - /* - Remove from the JOIN::all_fields list any reference to the elements - of the eliminated GROUP BY list unless it is 'in_field_list'. - This is needed in order not to confuse JOIN::make_aggr_tables_info() - when it constructs different structure for execution phase. - */ - List_iterator li(subq_select_lex->join->all_fields); - Item *item; - while ((item= li++)) - { - if (item == *ord->item) - li.remove(); - } + have_subquery= true; + break; } } - subq_select_lex->join->group_list= NULL; - subq_select_lex->group_list.empty(); - DBUG_PRINT("info", ("GROUP BY removed")); + + if (!have_subquery) + { + for (ORDER *ord= subq_select_lex->group_list.first; ord; ord= ord->next) + { + /* + Do not remove the item if it is used in select list and then referred + from GROUP BY clause by its name or number. Example: + + select (select ... ) as SUBQ ... group by SUBQ + + Here SUBQ cannot be removed. + */ + if (!ord->in_field_list) + { + /* + Not necessary due to workaround for MDEV-28621: + (*ord->item)->walk(&Item::eliminate_subselect_processor, FALSE, NULL); + */ + /* + Remove from the JOIN::all_fields list any reference to the elements + of the eliminated GROUP BY list unless it is 'in_field_list'. + This is needed in order not to confuse JOIN::make_aggr_tables_info() + when it constructs different structure for execution phase. + */ + List_iterator li(subq_select_lex->join->all_fields); + Item *item; + while ((item= li++)) + { + if (item == *ord->item) + li.remove(); + } + } + } + subq_select_lex->join->group_list= NULL; + subq_select_lex->group_list.empty(); + DBUG_PRINT("info", ("GROUP BY removed")); + } } /*