You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
MDEV-28621: group by optimization incorrectly removing subquery where subject buried in a function
Workaround patch: Do not remove GROUP BY clause when it has
subquer(ies) in it.
remove_redundant_subquery_clauses() removes redundant GROUP BY clause
from queries in form:
expr IN (SELECT no_aggregates GROUP BY ...)
expr {CMP} {ALL|ANY|SOME} (SELECT no_aggregates GROUP BY ...)
This hits problems when the GROUP BY clause itself has subquer(y/ies).
This patch is just a workaround: it disables removal of GROUP BY clause
if the clause has one or more subqueries in it.
Tests:
- subselect_elimination.test has all known crashing cases.
- subselect4.result, insert_select.result are updated.
Note that in some cases results of SELECT are changed too (not just
EXPLAINs). These are caused by non-deterministic SQL: when running a
query like:
x > ANY( SELECT col1 FROM t1 GROUP BY constant_expression)
without removing the GROUP BY, the executor is free to pick the value
of t1.col1 from any row in the GROUP BY group (denote it $COL1_VAL).
Then, it computes x > ANY(SELECT $COL1_VAL).
When running the same query and removing the GROUP BY:
x > ANY( SELECT col1 FROM t1)
the executor will actually check all rows of t1.
Copy file name to clipboardExpand all lines: mysql-test/main/subselect4.result
+28-22Lines changed: 28 additions & 22 deletions
Original file line number
Diff line number
Diff line change
@@ -2979,48 +2979,44 @@ where a >= any (select b from t2 group by (select c from t3 where c = 1));
2979
2979
id select_type table type possible_keys key key_len ref rows filtered Extra
2980
2980
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where
2981
2981
2 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00
2982
+
3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where
2982
2983
Warnings:
2983
-
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <nop>(<in_optimizer>(`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) <= <cache>(`test`.`t1`.`a`)))
2984
+
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <nop>(<in_optimizer>(`test`.`t1`.`a`,<min>(/* 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)) <= <cache>(`test`.`t1`.`a`)))
2984
2985
select a from t1
2985
2986
where a >= any (select b from t2 group by (select c from t3 where c = 1));
2986
2987
a
2987
-
3
2988
-
2
2989
2988
prepare stmt from "select a from t1
2990
2989
where a >= any (select b from t2 group by (select c from t3 where c = 1))";
2991
2990
execute stmt;
2992
2991
a
2993
-
3
2994
-
2
2995
2992
execute stmt;
2996
2993
a
2997
-
3
2998
-
2
2999
2994
deallocate prepare stmt;
3000
2995
explain extended select a from t1
3001
2996
where a <= all (select b from t2 group by (select c from t3 where c = 1));
3002
2997
id select_type table type possible_keys key key_len ref rows filtered Extra
3003
2998
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where
3004
2999
2 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00
3000
+
3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where
3005
3001
Warnings:
3006
-
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <not>(<in_optimizer>(`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) < <cache>(`test`.`t1`.`a`)))
3002
+
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <not>(<in_optimizer>(`test`.`t1`.`a`,<min>(/* 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)) < <cache>(`test`.`t1`.`a`)))
3007
3003
select a from t1
3008
3004
where a <= all (select b from t2 group by (select c from t3 where c = 1));
3009
3005
a
3006
+
3
3010
3007
1
3011
3008
2
3012
3009
explain extended select a from t1
3013
3010
where a >= any (select b from t2 group by 1 + (select c from t3 where c = 1));
3014
3011
id select_type table type possible_keys key key_len ref rows filtered Extra
3015
3012
1 PRIMARY t1 ALL NULL NULL NULL NULL 3 100.00 Using where
3016
3013
2 SUBQUERY t2 ALL NULL NULL NULL NULL 2 100.00
3014
+
3 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00 Using where
3017
3015
Warnings:
3018
-
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <nop>(<in_optimizer>(`test`.`t1`.`a`,(/* select#2 */ select min(`test`.`t2`.`b`) from `test`.`t2`) <= <cache>(`test`.`t1`.`a`)))
3016
+
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where <nop>(<in_optimizer>(`test`.`t1`.`a`,<min>(/* 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)) <= <cache>(`test`.`t1`.`a`)))
3019
3017
select a from t1
3020
3018
where a >= any (select b from t2 group by 1 + (select c from t3 where c = 1));
3021
3019
a
3022
-
3
3023
-
2
3024
3020
drop table t1,t2,t3;
3025
3021
#
3026
3022
# 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));
3040
3036
id select_type table type possible_keys key key_len ref rows filtered Extra
3041
3037
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00
3042
3038
2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00
3039
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3040
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3043
3041
Warnings:
3044
-
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1
3042
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <in_optimizer>(1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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))
3045
3043
select b from t2
3046
3044
where exists (select c from t3
3047
3045
group by (select a from t1 where a = 1) in (select d from t4));
@@ -3067,8 +3065,10 @@ any (select d from t4));
3067
3065
id select_type table type possible_keys key key_len ref rows filtered Extra
3068
3066
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00
3069
3067
2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00
3068
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3069
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3070
3070
Warnings:
3071
-
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1
3071
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <in_optimizer>(1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <nop>(<expr_cache><(/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)>(<in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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))
3072
3072
select b from t2
3073
3073
where exists (select c from t3
3074
3074
group by (select a from t1 where a = 1) >=
@@ -3083,8 +3083,10 @@ all (select d from t4));
3083
3083
id select_type table type possible_keys key key_len ref rows filtered Extra
3084
3084
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00
3085
3085
2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00
3086
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3087
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3086
3088
Warnings:
3087
-
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where 1
3089
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <in_optimizer>(1,exists(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <not>(<expr_cache><(/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1)>(<in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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))
3088
3090
select b from t2
3089
3091
where exists (select c from t3
3090
3092
group by (select a from t1 where a = 1) <
@@ -3096,46 +3098,50 @@ explain extended select b from t2
3096
3098
where b in (select c from t3
3097
3099
group by (select a from t1 where a = 1) in (select d from t4));
3098
3100
id select_type table type possible_keys key key_len ref rows filtered Extra
2 MATERIALIZED t3 ALL NULL NULL NULL NULL 2 100.00
3104
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3105
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3102
3106
Warnings:
3103
-
Note 1003 select`test`.`t2`.`b` AS `b` from `test`.`t2` semi join (`test`.`t3`) where 1
3107
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from <materialize> (/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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 `<subquery2>`.`c` = `test`.`t2`.`b`
3104
3108
select b from t2
3105
3109
where b in (select c from t3
3106
3110
group by (select a from t1 where a = 1) in (select d from t4));
3107
3111
b
3108
-
2
3109
3112
explain extended select b from t2
3110
3113
where b >= any (select c from t3
3111
3114
group by (select a from t1 where a = 1) in
3112
3115
(select d from t4));
3113
3116
id select_type table type possible_keys key key_len ref rows filtered Extra
3114
3117
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where
3115
3118
2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00
3119
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3120
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3116
3121
Warnings:
3117
-
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <nop>(<in_optimizer>(`test`.`t2`.`b`,(/* select#2 */ select min(`test`.`t3`.`c`) from `test`.`t3`) <= <cache>(`test`.`t2`.`b`)))
3122
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <nop>(<in_optimizer>(`test`.`t2`.`b`,<min>(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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)))) <= <cache>(`test`.`t2`.`b`)))
3118
3123
select b from t2
3119
3124
where b >= any (select c from t3
3120
3125
group by (select a from t1 where a = 1) in
3121
3126
(select d from t4));
3122
3127
b
3123
-
3
3124
-
2
3125
3128
explain extended select b from t2
3126
3129
where b <= all (select c from t3
3127
3130
group by (select a from t1 where a = 1) in
3128
3131
(select d from t4));
3129
3132
id select_type table type possible_keys key key_len ref rows filtered Extra
3130
3133
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00 Using where
3131
3134
2 SUBQUERY t3 ALL NULL NULL NULL NULL 2 100.00
3135
+
4 SUBQUERY t4 ALL NULL NULL NULL NULL 2 100.00 Using where
3136
+
3 SUBQUERY t1 ALL NULL NULL NULL NULL 2 100.00 Using where
3132
3137
Warnings:
3133
-
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <not>(<in_optimizer>(`test`.`t2`.`b`,<min>(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3`) < <cache>(`test`.`t2`.`b`)))
3138
+
Note 1003 /* select#1 */ select `test`.`t2`.`b` AS `b` from `test`.`t2` where <not>(<in_optimizer>(`test`.`t2`.`b`,<min>(/* select#2 */ select `test`.`t3`.`c` from `test`.`t3` group by <in_optimizer>((/* select#3 */ select `test`.`t1`.`a` from `test`.`t1` where `test`.`t1`.`a` = 1),<exists>(/* select#4 */ select `test`.`t4`.`d` from `test`.`t4` where trigcond(<cache>((/* 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)))) < <cache>(`test`.`t2`.`b`)))
0 commit comments