Skip to content

Commit b34bb81

Browse files
committed
MDEV-25112 MIN/MAX aggregation over an indexed column may return wrong result
If a query with implicit grouping contains in MIN/MAX set function in the select list over a column that is a part of an index then the query might be subject to MIN/MAX optimization. With this optimization the server performs a look-up into an index, fetches a value of the column C used in the MIN/MAX function and substitute the MIN/MAX expression for this value. This allows to eliminate the table containing C from further join processing. In order the optimization to be applied the WHERE condition must be a conjunction of simple equality/inequality predicates or/and BETWEEN predicates. The bug fixed in the patch resulted in fetching a wrong value from the index used for MIN/MAX optimization. It may happened when a BETWEEN predicate containing the MIN/MAX value followed a strict inequality. Approved by dmitry.shulga@mariadb.com
1 parent c557e95 commit b34bb81

File tree

3 files changed

+65
-0
lines changed

3 files changed

+65
-0
lines changed

mysql-test/r/func_group.result

Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2458,3 +2458,37 @@ select count(*)+sleep(0) from t1;
24582458
count(*)+sleep(0)
24592459
2
24602460
drop table t1;
2461+
#
2462+
# MDEV-25112: MIN/MAX optimization for query containing BETWEEN in WHERE
2463+
#
2464+
create table t1 (a int) engine=myisam;
2465+
insert into t1 values (267), (273), (287), (303), (308);
2466+
select max(a) from t1 where a < 303 and (a between 267 AND 287);
2467+
max(a)
2468+
287
2469+
explain select max(a) from t1 where a < 303 and (a between 267 AND 287);
2470+
id select_type table type possible_keys key key_len ref rows Extra
2471+
1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where
2472+
select min(a) from t1 where a > 267 and (a between 273 AND 303);
2473+
min(a)
2474+
273
2475+
explain select min(a) from t1 where a > 267 and (a between 273 AND 303);
2476+
id select_type table type possible_keys key key_len ref rows Extra
2477+
1 SIMPLE t1 ALL NULL NULL NULL NULL 5 Using where
2478+
create index idx on t1(a);
2479+
select max(a) from t1 where a < 303 and (a between 267 AND 287);
2480+
max(a)
2481+
287
2482+
explain select max(a) from t1 where a < 303 and (a between 267 AND 287);
2483+
id select_type table type possible_keys key key_len ref rows Extra
2484+
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
2485+
select min(a) from t1 where a > 267 and (a between 273 AND 303);
2486+
min(a)
2487+
273
2488+
explain select min(a) from t1 where a > 267 and (a between 273 AND 303);
2489+
id select_type table type possible_keys key key_len ref rows Extra
2490+
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
2491+
drop table t1;
2492+
#
2493+
# End of 10.2 tests
2494+
#

mysql-test/t/func_group.test

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1703,4 +1703,32 @@ select count(*)+sleep(0) from t1;
17031703

17041704
drop table t1;
17051705

1706+
--echo #
1707+
--echo # MDEV-25112: MIN/MAX optimization for query containing BETWEEN in WHERE
1708+
--echo #
1709+
1710+
create table t1 (a int) engine=myisam;
1711+
insert into t1 values (267), (273), (287), (303), (308);
1712+
1713+
let $q1=
1714+
select max(a) from t1 where a < 303 and (a between 267 AND 287);
1715+
let $q2=
1716+
select min(a) from t1 where a > 267 and (a between 273 AND 303);
1717+
1718+
eval $q1;
1719+
eval explain $q1;
1720+
eval $q2;
1721+
eval explain $q2;
1722+
1723+
create index idx on t1(a);
17061724

1725+
eval $q1;
1726+
eval explain $q1;
1727+
eval $q2;
1728+
eval explain $q2;
1729+
1730+
drop table t1;
1731+
1732+
--echo #
1733+
--echo # End of 10.2 tests
1734+
--echo #

sql/opt_sum.cc

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -830,7 +830,10 @@ static bool matching_cond(bool max_fl, TABLE_REF *ref, KEY *keyinfo,
830830
if (is_field_part)
831831
{
832832
if (between || eq_type)
833+
{
833834
*range_fl&= ~(NO_MAX_RANGE | NO_MIN_RANGE);
835+
*range_fl&= ~(max_fl ? NEAR_MAX : NEAR_MIN);
836+
}
834837
else
835838
{
836839
*range_fl&= ~(max_fl ? NO_MAX_RANGE : NO_MIN_RANGE);

0 commit comments

Comments
 (0)