Skip to content

Commit 21be9fb

Browse files
MDEV-37901: Wrong result on QUICK_GROUP_MIN_MAX_SELECT WITH TIES
The "FETCH FIRST n ROWS WITH TIES" was not enforced when the SELECT used "using index for group-by". This was caused by an optimization which removed the ORDER BY clause when the GROUP BY clause prescribed a compatible ordering. Other GROUP BY strategies used workarounds to still handle WITH TIES, see comment to using_with_ties_and_group_min_max() in this patch for details. QUICK_GROUP_MIN_MAX_SELECT didn't have a workaround. Fix this by disabling removal of ORDER BY when QUICK_GROUP_MIN_MAX_SELECT is used.
1 parent 9e8e215 commit 21be9fb

File tree

5 files changed

+206
-2
lines changed

5 files changed

+206
-2
lines changed

mysql-test/main/fetch_first.result

Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1406,3 +1406,88 @@ a b
14061406
3 bar
14071407
3 zzz
14081408
DROP TABLE t1;
1409+
#
1410+
# MDEV-37901: Wrong result with Loose Scan on QUICK_GROUP_MIN_MAX_SELECT WITH TIES
1411+
#
1412+
create table t1 (
1413+
country varchar(100),
1414+
city varchar(100),
1415+
user_score int,
1416+
index (country, city, user_score)
1417+
);
1418+
insert into t1
1419+
select 'China', 'Shenzhen', seq from seq_10_to_100;
1420+
insert into t1
1421+
select 'India', 'New Delhi', seq from seq_10_to_100;
1422+
insert into t1
1423+
select 'Sri Lanka', 'Colombo', seq from seq_10_to_100;
1424+
analyze table t1 persistent for all;
1425+
Table Op Msg_type Msg_text
1426+
test.t1 analyze status Engine-independent statistics collected
1427+
test.t1 analyze status OK
1428+
insert into t1
1429+
select 'Finland', 'Espoo', seq from seq_10_to_200;
1430+
insert into t1
1431+
select 'Greece', 'Chania', seq from seq_10_to_20;
1432+
insert into t1
1433+
select 'Estonia', 'Narva', seq from seq_10_to_20;
1434+
insert into t1
1435+
select 'Russia', 'St Petersburg', seq from seq_10_to_20;
1436+
# Must use "Using index for group-by":
1437+
explain
1438+
select country, city, min(user_score)
1439+
from t1
1440+
where user_score between 9 and 199
1441+
group by country, city
1442+
order by country
1443+
fetch first 5 rows with ties;
1444+
id select_type table type possible_keys key key_len ref rows Extra
1445+
1 SIMPLE t1 range NULL country 211 NULL 4 Using where; Using index for group-by; Using temporary; Using filesort
1446+
# Must not use "Using index for group-by":
1447+
explain
1448+
select country, city, sum(user_score)
1449+
from t1
1450+
where user_score between 9 and 199
1451+
group by country, concat(city,'AA')
1452+
order by country
1453+
fetch first 5 rows with ties;
1454+
id select_type table type possible_keys key key_len ref rows Extra
1455+
1 SIMPLE t1 index NULL country 211 NULL 273 Using where; Using index; Using temporary; Using filesort
1456+
select country, city, sum(user_score)
1457+
from t1
1458+
where user_score between 9 and 199
1459+
group by country, concat(city,'AA')
1460+
order by country
1461+
fetch first 5 rows with ties;
1462+
country city sum(user_score)
1463+
China Shenzhen 5005
1464+
Estonia Narva 165
1465+
Finland Espoo 19855
1466+
Greece Chania 165
1467+
India New Delhi 5005
1468+
# both using index and index with group by should produce same result
1469+
select country, city, min(user_score)
1470+
from t1
1471+
where user_score between 9 and 199
1472+
group by country, city
1473+
order by country
1474+
fetch first 5 rows with ties;
1475+
country city min(user_score)
1476+
China Shenzhen 10
1477+
Estonia Narva 10
1478+
Finland Espoo 10
1479+
Greece Chania 10
1480+
India New Delhi 10
1481+
select country, city, min(user_score)
1482+
from t1 use index()
1483+
where user_score between 9 and 199
1484+
group by country, city
1485+
order by country
1486+
fetch first 5 rows with ties;
1487+
country city min(user_score)
1488+
China Shenzhen 10
1489+
Estonia Narva 10
1490+
Finland Espoo 10
1491+
Greece Chania 10
1492+
India New Delhi 10
1493+
drop table t1;

mysql-test/main/fetch_first.test

Lines changed: 74 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1082,3 +1082,77 @@ SELECT DISTINCT a, b FROM t1 ORDER BY a FETCH FIRST 3 ROWS WITH TIES;
10821082

10831083
# Cleanup
10841084
DROP TABLE t1;
1085+
1086+
1087+
--echo #
1088+
--echo # MDEV-37901: Wrong result with Loose Scan on QUICK_GROUP_MIN_MAX_SELECT WITH TIES
1089+
--echo #
1090+
1091+
--source include/have_sequence.inc
1092+
1093+
create table t1 (
1094+
country varchar(100),
1095+
city varchar(100),
1096+
user_score int,
1097+
index (country, city, user_score)
1098+
);
1099+
1100+
insert into t1
1101+
select 'China', 'Shenzhen', seq from seq_10_to_100;
1102+
insert into t1
1103+
select 'India', 'New Delhi', seq from seq_10_to_100;
1104+
insert into t1
1105+
select 'Sri Lanka', 'Colombo', seq from seq_10_to_100;
1106+
analyze table t1 persistent for all;
1107+
1108+
insert into t1
1109+
select 'Finland', 'Espoo', seq from seq_10_to_200;
1110+
insert into t1
1111+
select 'Greece', 'Chania', seq from seq_10_to_20;
1112+
insert into t1
1113+
select 'Estonia', 'Narva', seq from seq_10_to_20;
1114+
insert into t1
1115+
select 'Russia', 'St Petersburg', seq from seq_10_to_20;
1116+
1117+
--echo # Must use "Using index for group-by":
1118+
explain
1119+
select country, city, min(user_score)
1120+
from t1
1121+
where user_score between 9 and 199
1122+
group by country, city
1123+
order by country
1124+
fetch first 5 rows with ties;
1125+
1126+
--echo # Must not use "Using index for group-by":
1127+
explain
1128+
select country, city, sum(user_score)
1129+
from t1
1130+
where user_score between 9 and 199
1131+
group by country, concat(city,'AA')
1132+
order by country
1133+
fetch first 5 rows with ties;
1134+
1135+
select country, city, sum(user_score)
1136+
from t1
1137+
where user_score between 9 and 199
1138+
group by country, concat(city,'AA')
1139+
order by country
1140+
fetch first 5 rows with ties;
1141+
1142+
--echo # both using index and index with group by should produce same result
1143+
1144+
select country, city, min(user_score)
1145+
from t1
1146+
where user_score between 9 and 199
1147+
group by country, city
1148+
order by country
1149+
fetch first 5 rows with ties;
1150+
1151+
select country, city, min(user_score)
1152+
from t1 use index()
1153+
where user_score between 9 and 199
1154+
group by country, city
1155+
order by country
1156+
fetch first 5 rows with ties;
1157+
1158+
drop table t1;

sql/opt_range.cc

Lines changed: 40 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -15227,6 +15227,46 @@ TRP_GROUP_MIN_MAX::make_quick(PARAM *param, bool retrieve_full_rows,
1522715227
}
1522815228

1522915229

15230+
/*
15231+
@brief
15232+
Return true if the select is using "Using index for group-by" and also
15233+
has "ORDER BY ... FETCH FIRST n ROWS WITH TIES"
15234+
15235+
@detail
15236+
There is a rewrite that removes the ORDER BY (JOIN::order) if the select
15237+
also has a GROUP BY that produces a compatible ordering.
15238+
However "FETCH FIRST ... WITH TIES" needs an ORDER BY clause (in
15239+
JOIN::alloc_order_fields()).
15240+
GROUP BY strategies handle it this way:
15241+
- For strategies using temporary table, JOIN::make_aggr_tables_info() will
15242+
put the ORDER BY clause back.
15243+
- OrderedGroupBy in end_send_group() handles WITH TIES with the GROUP BY
15244+
clause (note that SQL doesn't allow "GROUP BY ... WITH TIES").
15245+
- The remaining strategy is QUICK_GROUP_MIN_MAX_SELECT, for which
15246+
= the grouping strategy in the quick select doesn't handle WITH TIES.
15247+
= end_send() would not handle WITH TIES, because JOIN::order is removed.
15248+
15249+
The solution is to NOT remove ORDER BY when QUICK_GROUP_MIN_MAX_SELECT is
15250+
used.
15251+
15252+
Unfortunately, the optimizer then will not recognize that it can skip
15253+
sorting and will use filesort, which will prevent short-cutting the
15254+
execution when LIMIT is reached.
15255+
*/
15256+
15257+
bool using_with_ties_and_group_min_max(JOIN *join)
15258+
{
15259+
if (join->unit->lim.is_with_ties())
15260+
{
15261+
JOIN_TAB *tab= &join->join_tab[join->const_tables];
15262+
if (tab->select && tab->select->quick &&
15263+
tab->select->quick->get_type() ==
15264+
QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
15265+
return true;
15266+
}
15267+
return false;
15268+
}
15269+
1523015270
/*
1523115271
Construct new quick select for group queries with min/max.
1523215272

sql/opt_range.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1869,6 +1869,7 @@ class QUICK_GROUP_MIN_MAX_SELECT : public QUICK_SELECT_I
18691869
Explain_quick_select *get_explain(MEM_ROOT *alloc) override;
18701870
};
18711871

1872+
bool using_with_ties_and_group_min_max(JOIN *join);
18721873

18731874
class QUICK_SELECT_DESC: public QUICK_RANGE_SELECT
18741875
{

sql/sql_select.cc

Lines changed: 6 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -3182,9 +3182,14 @@ int JOIN::optimize_stage2()
31823182
(as MariaDB is by default sorting on GROUP BY) or
31833183
if there is no GROUP BY and aggregate functions are used
31843184
(as the result will only contain one row).
3185+
3186+
(1) - Do not remove ORDER BY if we have WITH TIES and are using
3187+
QUICK_GROUP_MIN_MAX_SELECT to handle GROUP BY. See the comment
3188+
for using_with_ties_and_group_min_max() for details.
31853189
*/
31863190
if (order && (test_if_subpart(group_list, order) ||
3187-
(!group_list && tmp_table_param.sum_func_count)))
3191+
(!group_list && tmp_table_param.sum_func_count)) &&
3192+
!using_with_ties_and_group_min_max(this)) // (1)
31883193
order=0;
31893194

31903195
// Can't use sort on head table if using join buffering
@@ -13652,7 +13657,6 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
1365213657

1365313658
if (build_tmp_join_prefix_cond(join, tab, &sel->cond))
1365413659
return true;
13655-
1365613660
/*
1365713661
We can't call sel->cond->fix_fields,
1365813662
as it will break tab->on_expr if it's AND condition

0 commit comments

Comments
 (0)