Skip to content

Commit c04adce

Browse files
committed
MDEV-26337: subquery with groupby and ROLLUP returns incorrect results on LEFT JOIN on INDEXED values
Disable LATERAL DERIVED optimization for subqueries that have WITH ROLLUP. This bug could affect queries with grouping derived tables / views / CTEs with ROLLUP. The bug could manifest itself if the corresponding materialized derived tables are subject to split optimization. The current implementation of the split optimization produces rows from the derived table in an arbitrary order. So these rows must be accumulated in another temporary table and sorted according to the used GROUP BY clause in order to be able to generate the additional ROLLUP rows. This patch prohibits to use split optimization for grouping derived tables / views / CTEs with ROLLUP.
1 parent 25f598f commit c04adce

File tree

3 files changed

+82
-1
lines changed

3 files changed

+82
-1
lines changed

mysql-test/main/derived_split_innodb.result

Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -234,4 +234,46 @@ id itemid id id
234234
4 2 4 2
235235
drop table t1,t2,t3;
236236
set optimizer_switch='split_materialized=default';
237+
#
238+
# MDEV-26337: subquery with groupby and ROLLUP returns incorrect results
239+
# (The testcase is taken from testcase for MDEV-13389 due to it being
240+
# much smaller)
241+
#
242+
create table t3 (a int, b int, c char(127), index idx_b(b)) engine=myisam;
243+
insert into t3 values
244+
(8,11,'aa'), (5,15,'cc'), (1,14,'bb'), (2,12,'aa'), (7,17,'cc'),
245+
(7,18,'aa'), (2,11,'aa'), (7,10,'bb'), (3,11,'dd'), (4,12,'ee'),
246+
(5,14,'dd'), (9,12,'ee');
247+
create table t4 (a int, b int, c char(127), index idx(a,c)) engine=myisam;
248+
insert into t4 values
249+
(7,10,'cc'), (1,20,'aa'), (2,23,'bb'), (7,18,'cc'), (1,30,'bb'),
250+
(4,71,'xx'), (3,15,'aa'), (7,82,'aa'), (8,12,'dd'), (4,15,'aa'),
251+
(11,33,'yy'), (10,42,'zz'), (4,53,'xx'), (10,17,'yy'), (7,12,'cc'),
252+
(8,20,'dd'), (7,32,'bb'), (1,50,'aa'), (3,40,'bb'), (3,77,'aa');
253+
insert into t4 select a+10, b+10, concat(c,'f') from t4;
254+
analyze table t3,t4;
255+
Table Op Msg_type Msg_text
256+
test.t3 analyze status OK
257+
test.t4 analyze status OK
258+
# This should use a plan with LATERAL DERIVED:
259+
explain select t3.a,t3.c,t.max,t.min
260+
from t3 join
261+
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
262+
on t3.a=t.a and t3.c=t.c
263+
where t3.b > 15;
264+
id select_type table type possible_keys key key_len ref rows Extra
265+
1 PRIMARY t3 range idx_b idx_b 5 NULL 3 Using index condition; Using where
266+
1 PRIMARY <derived2> ref key0 key0 133 test.t3.a,test.t3.c 2
267+
2 LATERAL DERIVED t4 ref idx idx 133 test.t3.a,test.t3.c 1
268+
# ... and if one adds WITH ROLLUP, then LATERAL DERIVED is no longer used:
269+
explain select t3.a,t3.c,t.max,t.min
270+
from t3 join
271+
(select a, c, max(b) max, min(b) min from t4 group by a,c with rollup) t
272+
on t3.a=t.a and t3.c=t.c
273+
where t3.b > 15;
274+
id select_type table type possible_keys key key_len ref rows Extra
275+
1 PRIMARY t3 range idx_b idx_b 5 NULL 3 Using index condition; Using where
276+
1 PRIMARY <derived2> ref key0 key0 133 test.t3.a,test.t3.c 4
277+
2 DERIVED t4 ALL NULL NULL NULL NULL 40 Using filesort
278+
drop table t3, t4;
237279
# End of 10.3 tests

mysql-test/main/derived_split_innodb.test

Lines changed: 36 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -186,4 +186,40 @@ eval $q;
186186
drop table t1,t2,t3;
187187
set optimizer_switch='split_materialized=default';
188188

189+
--echo #
190+
--echo # MDEV-26337: subquery with groupby and ROLLUP returns incorrect results
191+
--echo # (The testcase is taken from testcase for MDEV-13389 due to it being
192+
--echo # much smaller)
193+
--echo #
194+
195+
create table t3 (a int, b int, c char(127), index idx_b(b)) engine=myisam;
196+
insert into t3 values
197+
(8,11,'aa'), (5,15,'cc'), (1,14,'bb'), (2,12,'aa'), (7,17,'cc'),
198+
(7,18,'aa'), (2,11,'aa'), (7,10,'bb'), (3,11,'dd'), (4,12,'ee'),
199+
(5,14,'dd'), (9,12,'ee');
200+
create table t4 (a int, b int, c char(127), index idx(a,c)) engine=myisam;
201+
insert into t4 values
202+
(7,10,'cc'), (1,20,'aa'), (2,23,'bb'), (7,18,'cc'), (1,30,'bb'),
203+
(4,71,'xx'), (3,15,'aa'), (7,82,'aa'), (8,12,'dd'), (4,15,'aa'),
204+
(11,33,'yy'), (10,42,'zz'), (4,53,'xx'), (10,17,'yy'), (7,12,'cc'),
205+
(8,20,'dd'), (7,32,'bb'), (1,50,'aa'), (3,40,'bb'), (3,77,'aa');
206+
insert into t4 select a+10, b+10, concat(c,'f') from t4;
207+
analyze table t3,t4;
208+
209+
--echo # This should use a plan with LATERAL DERIVED:
210+
explain select t3.a,t3.c,t.max,t.min
211+
from t3 join
212+
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
213+
on t3.a=t.a and t3.c=t.c
214+
where t3.b > 15;
215+
216+
--echo # ... and if one adds WITH ROLLUP, then LATERAL DERIVED is no longer used:
217+
explain select t3.a,t3.c,t.max,t.min
218+
from t3 join
219+
(select a, c, max(b) max, min(b) min from t4 group by a,c with rollup) t
220+
on t3.a=t.a and t3.c=t.c
221+
where t3.b > 15;
222+
223+
drop table t3, t4;
224+
189225
--echo # End of 10.3 tests

sql/opt_split.cc

Lines changed: 4 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -310,6 +310,8 @@ struct SplM_field_ext_info: public SplM_field_info
310310
occurred also in the select list of this join
311311
9. There are defined some keys usable for ref access of fields from C
312312
with available statistics.
313+
10. The select doesn't use WITH ROLLUP (This limitation can probably be
314+
lifted)
313315
314316
@retval
315317
true if the answer is positive
@@ -326,7 +328,8 @@ bool JOIN::check_for_splittable_materialized()
326328
(unit->first_select()->next_select()) || // !(3)
327329
(derived->prohibit_cond_pushdown) || // !(4)
328330
(derived->is_recursive_with_table()) || // !(5)
329-
(table_count == 0 || const_tables == top_join_tab_count)) // !(6)
331+
(table_count == 0 || const_tables == top_join_tab_count) || // !(6)
332+
rollup.state != ROLLUP::STATE_NONE) // (10)
330333
return false;
331334
if (group_list) // (7.1)
332335
{

0 commit comments

Comments
 (0)