Skip to content

Commit f84f2ce

Browse files
MDEV-31887: wrong result with split optimization
Wrong result is produced when split-materialized optimization is used for grouping with order by and limit. The fix is to not let Split-Materialized optimization to happen when the sub-query has an ORDER BY with LIMIT, by returning FALSE early in the method opt_split.cc#check_for_splittable_materialized() However, with just the above change, there is a side-effect of NOT "using index for group by" in the scenario when all the following conditions are met: - 1. The query has derived table with GROUP BY and ORDER BY LIMIT 2. joined in a way that would allow Split-Materialized if ORDER BY LIMIT wasn't present 3. An index suitable for using "index for group-by" 4. No where clause so that, "using for group by" is applicable, but the index is not included in "possible_keys". The reason being, join_tab's "keys" field wasn't being set in sql_select.cc#make_join_select(). So, made this change as well as part of this PR.
1 parent 21be9fb commit f84f2ce

File tree

6 files changed

+108
-3
lines changed

6 files changed

+108
-3
lines changed

mysql-test/main/derived_split_innodb.result

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1002,5 +1002,48 @@ set statement optimizer_switch='split_materialized=off' for $query;
10021002
a b name total_amt
10031003
1 NULL A 10
10041004
DROP TABLE t1,t2;
1005+
#
1006+
# MDEV-37407 Wrong result with ORDER BY LIMIT
1007+
# Both, with and without split_materialized should
1008+
# produce the same results
1009+
#
1010+
SET @save_optimizer_switch= @@optimizer_switch;
1011+
CREATE TABLE t1
1012+
(a varchar(35), b varchar(4), KEY (a))
1013+
ENGINE=InnoDB;
1014+
INSERT INTO t1 VALUES
1015+
('Albania','AXA'), ('Australia','AUS'), ('Myanmar','MMR'),
1016+
('Bahamas','BS'), ('Brazil','BRA'), ('Barbados','BRB');
1017+
CREATE TABLE t2
1018+
(a varchar(4), b varchar(50), PRIMARY KEY (b,a), KEY (a))
1019+
ENGINE=InnoDB;
1020+
INSERT INTO t2 VALUES
1021+
('AUS','Anglican'), ('MMR','Baptist'), ('BS','Anglican'),
1022+
('BS','Baptist'), ('BS','Methodist'), ('BRB','Methodist'),
1023+
('BRA','Baptist'), ('USA','Baptist');
1024+
ANALYZE TABLE t1 PERSISTENT FOR ALL;
1025+
Table Op Msg_type Msg_text
1026+
test.t1 analyze status Engine-independent statistics collected
1027+
test.t1 analyze status OK
1028+
ANALYZE TABLE t2 PERSISTENT FOR ALL;
1029+
Table Op Msg_type Msg_text
1030+
test.t2 analyze status Engine-independent statistics collected
1031+
test.t2 analyze status OK
1032+
set optimizer_switch='split_materialized=off';
1033+
SELECT t1.a
1034+
FROM (SELECT a FROM t2 GROUP BY a ORDER BY a, COUNT(DISTINCT b) LIMIT 1) dt
1035+
JOIN t1 ON
1036+
dt.a=t1.b
1037+
WHERE t1.a LIKE 'B%';
1038+
a
1039+
set optimizer_switch='split_materialized=on';
1040+
SELECT t1.a
1041+
FROM (SELECT a FROM t2 GROUP BY a ORDER BY a, COUNT(DISTINCT b) LIMIT 1) dt
1042+
JOIN t1 ON
1043+
dt.a=t1.b
1044+
WHERE t1.a LIKE 'B%';
1045+
a
1046+
DROP TABLE t1,t2;
1047+
SET optimizer_switch= @save_optimizer_switch;
10051048
# End of 10.11 tests
10061049
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

mysql-test/main/derived_split_innodb.test

Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -620,5 +620,49 @@ evalp set statement optimizer_switch='split_materialized=off' for $query;
620620

621621
DROP TABLE t1,t2;
622622

623+
--echo #
624+
--echo # MDEV-37407 Wrong result with ORDER BY LIMIT
625+
--echo # Both, with and without split_materialized should
626+
--echo # produce the same results
627+
--echo #
628+
629+
SET @save_optimizer_switch= @@optimizer_switch;
630+
631+
CREATE TABLE t1
632+
(a varchar(35), b varchar(4), KEY (a))
633+
ENGINE=InnoDB;
634+
635+
INSERT INTO t1 VALUES
636+
('Albania','AXA'), ('Australia','AUS'), ('Myanmar','MMR'),
637+
('Bahamas','BS'), ('Brazil','BRA'), ('Barbados','BRB');
638+
639+
CREATE TABLE t2
640+
(a varchar(4), b varchar(50), PRIMARY KEY (b,a), KEY (a))
641+
ENGINE=InnoDB;
642+
643+
INSERT INTO t2 VALUES
644+
('AUS','Anglican'), ('MMR','Baptist'), ('BS','Anglican'),
645+
('BS','Baptist'), ('BS','Methodist'), ('BRB','Methodist'),
646+
('BRA','Baptist'), ('USA','Baptist');
647+
648+
ANALYZE TABLE t1 PERSISTENT FOR ALL;
649+
ANALYZE TABLE t2 PERSISTENT FOR ALL;
650+
651+
let $q=
652+
SELECT t1.a
653+
FROM (SELECT a FROM t2 GROUP BY a ORDER BY a, COUNT(DISTINCT b) LIMIT 1) dt
654+
JOIN t1 ON
655+
dt.a=t1.b
656+
WHERE t1.a LIKE 'B%';
657+
658+
set optimizer_switch='split_materialized=off';
659+
eval $q;
660+
661+
set optimizer_switch='split_materialized=on';
662+
eval $q;
663+
664+
DROP TABLE t1,t2;
665+
666+
SET optimizer_switch= @save_optimizer_switch;
623667
--echo # End of 10.11 tests
624668
SET GLOBAL innodb_stats_persistent=@save_innodb_stats_persistent;

mysql-test/main/distinct.result

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -212,7 +212,7 @@ id select_type table type possible_keys key key_len ref rows Extra
212212
1 SIMPLE t1 index NULL PRIMARY 4 NULL 1 Using index
213213
explain SELECT distinct a from t3 order by a desc limit 2;
214214
id select_type table type possible_keys key key_len ref rows Extra
215-
1 SIMPLE t3 index NULL a 5 NULL 40 Using index
215+
1 SIMPLE t3 range a a 5 NULL 10 Using index for group-by; Using temporary; Using filesort
216216
explain SELECT distinct a,b from t3 order by a+1;
217217
id select_type table type possible_keys key key_len ref rows Extra
218218
1 SIMPLE t3 ALL NULL NULL NULL NULL 204 Using temporary; Using filesort

mysql-test/main/group_min_max.result

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2451,7 +2451,7 @@ EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE EXISTS
24512451
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2);
24522452
id select_type table type possible_keys key key_len ref rows Extra
24532453
1 PRIMARY t1_outer index NULL a 10 NULL 15 Using index
2454-
2 SUBQUERY t1 index NULL a 10 NULL 15 Using index
2454+
2 SUBQUERY t1 range a a 5 NULL 6 Using index for group-by
24552455
EXPLAIN SELECT 1 FROM t1 AS t1_outer WHERE
24562456
(SELECT max(b) FROM t1 GROUP BY a HAVING a < 2) > 12;
24572457
id select_type table type possible_keys key key_len ref rows Extra

sql/opt_split.cc

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -355,6 +355,7 @@ struct SplM_field_ext_info: public SplM_field_info
355355
with available statistics.
356356
10. The select doesn't use WITH ROLLUP (This limitation can probably be
357357
lifted)
358+
11. The select doesn't have ORDER BY with LIMIT
358359
359360
@retval
360361
true if the answer is positive
@@ -388,6 +389,9 @@ bool JOIN::check_for_splittable_materialized()
388389
if (!partition_list)
389390
return false;
390391

392+
if (select_lex->order_list.elements > 0 && !unit->lim.is_unlimited()) //!(11)
393+
return false;
394+
391395
Json_writer_object trace_wrapper(thd);
392396
Json_writer_object trace_split(thd, "check_split_materialized");
393397

sql/sql_select.cc

Lines changed: 15 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13657,7 +13657,21 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
1365713657

1365813658
if (build_tmp_join_prefix_cond(join, tab, &sel->cond))
1365913659
return true;
13660-
/*
13660+
13661+
/*
13662+
To be removed in 11.0+:
13663+
Caution: we can reach this point with quick=NULL. Below, we'll
13664+
use tab->keys and not tab->const_keys like
13665+
get_quick_record_count() did. If we have constructed a
13666+
group-min-max quick select, make sure we're able to construct it
13667+
again
13668+
*/
13669+
if (sel->quick && sel->quick->get_type() ==
13670+
QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
13671+
{
13672+
tab->keys.set_bit(sel->quick->index);
13673+
}
13674+
/*
1366113675
We can't call sel->cond->fix_fields,
1366213676
as it will break tab->on_expr if it's AND condition
1366313677
(fix_fields currently removes extra AND/OR levels).

0 commit comments

Comments
 (0)