Skip to content

Commit

Permalink
MDEV-27576 Use reverse index for max/min optimization
Browse files Browse the repository at this point in the history
We use a bool to indicate that the key part used is a descending
index, which will flip the functions and flags used in
get_index_max_value() and get_index_min_value(), that allows correct
optimization for max/min for descending index.
  • Loading branch information
mariadb-YuchenPei committed Dec 14, 2023
1 parent 70de407 commit 875377a
Show file tree
Hide file tree
Showing 3 changed files with 380 additions and 18 deletions.
179 changes: 179 additions & 0 deletions mysql-test/main/desc_index_min_max.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,179 @@
#
# MDEV-27576 Use DESC indexes for MIN/MAX optimization
#
create or replace table t1 (a int, key(a desc)) engine=innodb;
insert into t1 select seq * 2 from seq_1_to_100 order by rand(1);
explain select max(a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1;
max(a)
200
explain select min(a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1;
min(a)
2
explain select max(a) from t1 where a < 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a < 100;
max(a)
98
explain select min(a) from t1 where a > 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a > 100;
min(a)
102
explain select max(a) from t1 where a <= 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a <= 100;
max(a)
100
explain select min(a) from t1 where a >= 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a >= 100;
min(a)
100
explain select max(a) from t1 where a <= 99;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a <= 99;
max(a)
98
explain select min(a) from t1 where a >= 99;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a >= 99;
min(a)
100
explain select max(a) from t1 where a > 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a > 100;
max(a)
200
explain select max(a) from t1 where a > 1000;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No matching min/max row
select max(a) from t1 where a > 1000;
max(a)
NULL
explain select min(a) from t1 where a < 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a < 100;
min(a)
2
explain select min(a) from t1 where a < 0;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No matching min/max row
select min(a) from t1 where a < 0;
min(a)
NULL
explain select max(a) from t1 where a >= 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a >= 100;
max(a)
200
explain select max(a) from t1 where a >= 1000;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No matching min/max row
select max(a) from t1 where a >= 1000;
max(a)
NULL
explain select min(a) from t1 where a <= 100;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a <= 100;
min(a)
2
explain select min(a) from t1 where a <= 0;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No matching min/max row
select min(a) from t1 where a <= 0;
min(a)
NULL
explain select max(a) from t1 where a >= 99;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1 where a >= 99;
max(a)
200
explain select min(a) from t1 where a <= 99;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1 where a <= 99;
min(a)
2
explain select max(200 - a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL a 5 NULL 100 Using index
select max(200 - a) from t1;
max(200 - a)
198
explain select min(200 - a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL a 5 NULL 100 Using index
select min(200 - a) from t1;
min(200 - a)
0
create or replace table t1 (a int, b int, key(a desc, b asc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);
explain select max(a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(a) from t1;
max(a)
200
explain select min(a) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(a) from t1;
min(a)
2
create or replace table t1 (a int, b int, key(a asc), key (b desc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);
explain select max(b) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(b) from t1;
max(b)
200
explain select min(b) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(b) from t1;
min(b)
2
create or replace table t1 (a int, b int, key (b desc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);
explain select max(b) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select max(b) from t1;
max(b)
200
explain select min(b) from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
select min(b) from t1;
min(b)
2
CREATE OR REPLACE TABLE t1 (a FLOAT, KEY (a DESC));
INSERT INTO t1 VALUES (0.1234),(0.6789);
explain SELECT MAX(a) FROM t1 WHERE a <= 0.6789;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Select tables optimized away
SELECT MAX(a) FROM t1 WHERE a <= 0.6789;
MAX(a)
0.6789
drop table t1;
#
# end of test 11.4
#
165 changes: 165 additions & 0 deletions mysql-test/main/desc_index_min_max.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,165 @@
--echo #
--echo # MDEV-27576 Use DESC indexes for MIN/MAX optimization
--echo #
--source include/have_sequence.inc
--source include/have_innodb.inc

create or replace table t1 (a int, key(a desc)) engine=innodb;
insert into t1 select seq * 2 from seq_1_to_100 order by rand(1);

let $query=
select max(a) from t1;
eval explain $query;
eval $query;

let $query=
select min(a) from t1;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a < 100;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a > 100;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a <= 100;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a >= 100;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a <= 99;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a >= 99;
eval explain $query;
eval $query;

# the other side

let $query=
select max(a) from t1 where a > 100;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a > 1000;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a < 100;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a < 0;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a >= 100;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a >= 1000;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a <= 100;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a <= 0;
eval explain $query;
eval $query;

let $query=
select max(a) from t1 where a >= 99;
eval explain $query;
eval $query;

let $query=
select min(a) from t1 where a <= 99;
eval explain $query;
eval $query;

# double reversion
let $query=
select max(200 - a) from t1;
eval explain $query;
eval $query;

let $query=
select min(200 - a) from t1;
eval explain $query;
eval $query;

# more complex key situations
create or replace table t1 (a int, b int, key(a desc, b asc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);

let $query=
select max(a) from t1;
eval explain $query;
eval $query;

let $query=
select min(a) from t1;
eval explain $query;
eval $query;

create or replace table t1 (a int, b int, key(a asc), key (b desc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);

let $query=
select max(b) from t1;
eval explain $query;
eval $query;

let $query=
select min(b) from t1;
eval explain $query;
eval $query;

create or replace table t1 (a int, b int, key (b desc)) engine=innodb;
insert into t1 select seq * 2, seq * 2 from seq_1_to_100 order by rand(1);

let $query=
select max(b) from t1;
eval explain $query;
eval $query;

let $query=
select min(b) from t1;
eval explain $query;
eval $query;

# float example in the comment
CREATE OR REPLACE TABLE t1 (a FLOAT, KEY (a DESC));
INSERT INTO t1 VALUES (0.1234),(0.6789);
let $query=
SELECT MAX(a) FROM t1 WHERE a <= 0.6789;
eval explain $query;
eval $query;

# Cleanup
drop table t1;
--echo #
--echo # end of test 11.4
--echo #

0 comments on commit 875377a

Please sign in to comment.