Commit 875377ad authored by Yuchen Pei's avatar Yuchen Pei

MDEV-27576 Use reverse index for max/min optimization

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.
parent 70de4075
#
# 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
#
--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 #
......@@ -55,7 +55,7 @@
static bool find_key_for_maxmin(bool max_fl, TABLE_REF *ref, Field* field,
COND *cond, uint *range_fl,
uint *key_prefix_length);
uint *key_prefix_length, bool *reverse);
static int reckey_in_range(bool max_fl, TABLE_REF *ref, Field* field,
COND *cond, uint range_fl, uint prefix_len);
static int maxmin_in_range(bool max_fl, Field* field, COND *cond);
......@@ -101,6 +101,7 @@ static ulonglong get_exact_record_count(List<TABLE_LIST> &tables)
@item_field Field used in MIN()
@range_fl Whether range endpoint is strict less than
@prefix_len Length of common key part for the range
@reverse Whether key part used is reverse descending index
@retval
0 No errors
......@@ -109,12 +110,15 @@ static ulonglong get_exact_record_count(List<TABLE_LIST> &tables)
static int get_index_min_value(TABLE *table, TABLE_REF *ref,
Item_field *item_field, uint range_fl,
uint prefix_len)
uint prefix_len, bool reverse)
{
int error;
if (!ref->key_length)
error= table->file->ha_index_first(table->record[0]);
{
error= reverse ? table->file->ha_index_last(table->record[0]) :
table->file->ha_index_first(table->record[0]);
}
else
{
/*
......@@ -139,6 +143,8 @@ static int get_index_min_value(TABLE *table, TABLE_REF *ref,
error= table->file->ha_index_read_map(table->record[0],
ref->key_buff,
make_prev_keypart_map(ref->key_parts),
reverse ?
HA_READ_PREFIX_LAST_OR_PREV :
HA_READ_KEY_OR_NEXT);
else
{
......@@ -154,6 +160,7 @@ static int get_index_min_value(TABLE *table, TABLE_REF *ref,
error= table->file->ha_index_read_map(table->record[0],
ref->key_buff,
make_prev_keypart_map(ref->key_parts),
reverse ? HA_READ_BEFORE_KEY :
HA_READ_AFTER_KEY);
/*
If the found record is outside the group formed by the search
......@@ -194,21 +201,31 @@ static int get_index_min_value(TABLE *table, TABLE_REF *ref,
@param table Table object
@param ref Reference to the structure where we store the key value
@range_fl Whether range endpoint is strict greater than
@reverse Whether the key part used is reverse descending index
@retval
0 No errors
HA_ERR_... Otherwise
*/
static int get_index_max_value(TABLE *table, TABLE_REF *ref, uint range_fl)
static int get_index_max_value(TABLE *table, TABLE_REF *ref, uint range_fl,
bool reverse)
{
return (ref->key_length ?
table->file->ha_index_read_map(table->record[0], ref->key_buff,
make_prev_keypart_map(ref->key_parts),
range_fl & NEAR_MAX ?
HA_READ_BEFORE_KEY :
HA_READ_PREFIX_LAST_OR_PREV) :
table->file->ha_index_last(table->record[0]));
if (ref->key_length)
{
return table->file->ha_index_read_map(table->record[0], ref->key_buff,
make_prev_keypart_map(ref->key_parts),
range_fl & NEAR_MAX ?
(reverse ? HA_READ_AFTER_KEY :
HA_READ_BEFORE_KEY) :
(reverse ? HA_READ_KEY_OR_NEXT :
HA_READ_PREFIX_LAST_OR_PREV));
}
else
{
return reverse ? table->file->ha_index_first(table->record[0]) :
table->file->ha_index_last(table->record[0]);
}
}
......@@ -378,6 +395,7 @@ int opt_sum_query(THD *thd,
uchar key_buff[MAX_KEY_LENGTH];
TABLE_REF ref;
uint range_fl, prefix_len;
bool reverse= false;
ref.key_buff= key_buff;
Item_field *item_field= (Item_field*) (expr->real_item());
......@@ -393,7 +411,7 @@ int opt_sum_query(THD *thd,
*/
if (table->file->inited || (outer_tables & table->map) ||
!find_key_for_maxmin(is_max, &ref, item_field->field, conds,
&range_fl, &prefix_len))
&range_fl, &prefix_len, &reverse))
{
const_result= 0;
break;
......@@ -407,9 +425,9 @@ int opt_sum_query(THD *thd,
if (likely(!(error= table->file->ha_index_init((uint) ref.key,
1))))
error= (is_max ?
get_index_max_value(table, &ref, range_fl) :
get_index_max_value(table, &ref, range_fl, reverse) :
get_index_min_value(table, &ref, item_field, range_fl,
prefix_len));
prefix_len, reverse));
}
/* Verify that the read tuple indeed matches the search key */
if (!error &&
......@@ -899,6 +917,7 @@ static bool matching_cond(bool max_fl, TABLE_REF *ref, KEY *keyinfo,
@param[in] cond WHERE condition
@param[out] range_fl Bit flags for how to search if key is ok
@param[out] prefix_len Length of prefix for the search range
@param[out] reverse Whether the key part used is descending index
@note
This function may set field->table->key_read to true,
......@@ -914,7 +933,8 @@ static bool matching_cond(bool max_fl, TABLE_REF *ref, KEY *keyinfo,
static bool find_key_for_maxmin(bool max_fl, TABLE_REF *ref,
Field* field, COND *cond,
uint *range_fl, uint *prefix_len)
uint *range_fl, uint *prefix_len,
bool *reverse)
{
if (!(field->flags & PART_KEY_FLAG))
return FALSE; // Not key field
......@@ -953,9 +973,6 @@ static bool find_key_for_maxmin(bool max_fl, TABLE_REF *ref,
part->length < part_field->key_length())
break;
if (part->key_part_flag & HA_REVERSE_SORT)
break; // TODO MDEV-27576
if (field->eq(part->field))
{
ref->key= idx;
......@@ -997,6 +1014,7 @@ static bool find_key_for_maxmin(bool max_fl, TABLE_REF *ref,
*/
if (field->part_of_key.is_set(idx))
table->file->ha_start_keyread(idx);
*reverse= part->key_part_flag & HA_REVERSE_SORT ? true : false;
DBUG_RETURN(TRUE);
}
}
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment