Commit ff8d4009 authored by Sergei Petrunia's avatar Sergei Petrunia

MDEV-9457: Poor query plan chosen for ORDER BY query by a recent 10.1

Undo the change in test_if_skip_sort_order() that set ref_key=-1 when
a variant of index_merge is used (was made in fix for MDEV-9021).

It turned out that test_if_cheaper_ordering() call below assumes that
ref_key=-1 means "no index is used", that is, "an inefficient full table
scan is done".
This is not the same as index_merge, index_merge can actually be quite
efficient. So, ref_key=MAX_KEY denotes the fact that some index is used,
not any given index.
parent 825f51d1
...@@ -11,3 +11,40 @@ a b c d ...@@ -11,3 +11,40 @@ a b c d
8 NULL 9 NULL 8 NULL 9 NULL
8 NULL 10 NULL 8 NULL 10 NULL
DROP TABLE t1; DROP TABLE t1;
#
# MDEV-9457: Poor query plan chosen for ORDER BY query by a recent 10.1
#
create table t0 (a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t1 (
pk int primary key,
key1 int,
key2 int,
col1 char(255),
key(key1),
key(key2)
) engine=innodb;
set @a=-1;
insert into t1
select
@a:=@a+1,
@a,
@a,
repeat('abcd', 63)
from t0 A, t0 B, t0 C, t0 D;
# The following must NOT use 'index' on PK.
# It should use index_merge(key1,key2) + filesort
explain
select *
from t1
where key1<3 or key2<3
order by pk;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge key1,key2 key1,key2 5,5 NULL # Using sort_union(key1,key2); Using where; Using filesort
explain
select *
from t1
where key1<3 or key2<3;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge key1,key2 key1,key2 5,5 NULL # Using sort_union(key1,key2); Using where
drop table t0, t1;
...@@ -21,3 +21,43 @@ SELECT * FROM t1 WHERE a = 8 AND (b = 1 OR b IS NULL) ORDER BY c; ...@@ -21,3 +21,43 @@ SELECT * FROM t1 WHERE a = 8 AND (b = 1 OR b IS NULL) ORDER BY c;
DROP TABLE t1; DROP TABLE t1;
--echo #
--echo # MDEV-9457: Poor query plan chosen for ORDER BY query by a recent 10.1
--echo #
create table t0 (a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t1 (
pk int primary key,
key1 int,
key2 int,
col1 char(255),
key(key1),
key(key2)
) engine=innodb;
set @a=-1;
insert into t1
select
@a:=@a+1,
@a,
@a,
repeat('abcd', 63)
from t0 A, t0 B, t0 C, t0 D;
--echo # The following must NOT use 'index' on PK.
--echo # It should use index_merge(key1,key2) + filesort
--replace_column 9 #
explain
select *
from t1
where key1<3 or key2<3
order by pk;
--replace_column 9 #
explain
select *
from t1
where key1<3 or key2<3;
drop table t0, t1;
...@@ -20777,7 +20777,15 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit, ...@@ -20777,7 +20777,15 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit,
quick_type == QUICK_SELECT_I::QS_TYPE_INDEX_INTERSECT || quick_type == QUICK_SELECT_I::QS_TYPE_INDEX_INTERSECT ||
quick_type == QUICK_SELECT_I::QS_TYPE_ROR_UNION || quick_type == QUICK_SELECT_I::QS_TYPE_ROR_UNION ||
quick_type == QUICK_SELECT_I::QS_TYPE_ROR_INTERSECT) quick_type == QUICK_SELECT_I::QS_TYPE_ROR_INTERSECT)
ref_key= -1; {
/*
we set ref_key=MAX_KEY instead of -1, because test_if_cheaper ordering
assumes that "ref_key==-1" means doing full index scan.
(This is not very straightforward and we got into this situation for
historical reasons. Should be fixed at some point).
*/
ref_key= MAX_KEY;
}
else else
{ {
ref_key= select->quick->index; ref_key= select->quick->index;
...@@ -25442,8 +25450,12 @@ static bool get_range_limit_read_cost(const JOIN_TAB *tab, ...@@ -25442,8 +25450,12 @@ static bool get_range_limit_read_cost(const JOIN_TAB *tab,
@param table Table if tab == NULL or tab->table @param table Table if tab == NULL or tab->table
@param usable_keys Key map to find a cheaper key in @param usable_keys Key map to find a cheaper key in
@param ref_key @param ref_key
* 0 <= key < MAX_KEY - key number (hint) to start the search 0 <= key < MAX_KEY - Key that is currently used for finding
* -1 - no key number provided row
MAX_KEY - means index_merge is used
-1 - means we're currently not using an
index to find rows.
@param select_limit LIMIT value @param select_limit LIMIT value
@param [out] new_key Key number if success, otherwise undefined @param [out] new_key Key number if success, otherwise undefined
@param [out] new_key_direction Return -1 (reverse) or +1 if success, @param [out] new_key_direction Return -1 (reverse) or +1 if success,
...@@ -25472,7 +25484,6 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, ...@@ -25472,7 +25484,6 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table,
uint *saved_best_key_parts) uint *saved_best_key_parts)
{ {
DBUG_ENTER("test_if_cheaper_ordering"); DBUG_ENTER("test_if_cheaper_ordering");
DBUG_ASSERT(ref_key < int(MAX_KEY));
/* /*
Check whether there is an index compatible with the given order Check whether there is an index compatible with the given order
usage of which is cheaper than usage of the ref_key index (ref_key>=0) usage of which is cheaper than usage of the ref_key index (ref_key>=0)
...@@ -25537,7 +25548,7 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table, ...@@ -25537,7 +25548,7 @@ test_if_cheaper_ordering(const JOIN_TAB *tab, ORDER *order, TABLE *table,
Calculate the selectivity of the ref_key for REF_ACCESS. For Calculate the selectivity of the ref_key for REF_ACCESS. For
RANGE_ACCESS we use table->quick_condition_rows. RANGE_ACCESS we use table->quick_condition_rows.
*/ */
if (ref_key >= 0 && !is_hash_join_key_no(ref_key) && tab->type == JT_REF) if (ref_key >= 0 && ref_key != MAX_KEY && tab->type == JT_REF)
{ {
if (table->quick_keys.is_set(ref_key)) if (table->quick_keys.is_set(ref_key))
refkey_rows_estimate= table->quick_rows[ref_key]; refkey_rows_estimate= table->quick_rows[ref_key];
......
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