Skip to content

Commit 0540eac

Browse files
committed
MDEV-35180: ref_to_range rewrite causes poor query plan
(Variant 2: only allow rewrite for ref(const)) make_join_select() has a "ref_to_range" rewrite: it would rewrite any ref access to a range access on the same index if the latter uses more keyparts. It seems, he initial intent of this was to fix poor query plan choice in cases like t.keypart1=const AND t.keypart2 < 'foo' Due to deficiency in cost model, ref access could be picked while range would enumerate fewer rows and be cheaper. However, the condition also forces a rewrite in cases like: t.keypart1=prev_table.col AND t.keypart1<='foo' AND t.keypart2<'bar' Here, it can be that * keypart1=prev_table.col is highly selective * (keypart1, keypart2) <= ('foo', 'bar') is not at all selective. Still, the rewrite would be made and poor query plan chosen. Fixed this by only doing the rewrite if ref access was ref(const) so we can be certain that quick select also used these restrictions and will scan a subset of rows that ref access would scan.
1 parent 3a1cf2c commit 0540eac

File tree

5 files changed

+99
-10
lines changed

5 files changed

+99
-10
lines changed

mysql-test/main/join.result

Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3579,3 +3579,35 @@ id select_type table type possible_keys key key_len ref rows Extra
35793579
1 SIMPLE seq ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join)
35803580
drop table t1,t2;
35813581
set @@optimizer_adjust_secondary_key_costs=default;
3582+
#
3583+
# MDEV-35180: ref_to_range rewrite causes poor query plan
3584+
#
3585+
create table t1 (a int);
3586+
insert into t1 select seq from seq_1_to_100;
3587+
create table t2 (
3588+
kp1 int,
3589+
kp2 int,
3590+
filler char(100),
3591+
key(kp1, kp2)
3592+
);
3593+
insert into t2
3594+
select
3595+
seq, seq,
3596+
'filler-data'
3597+
from seq_1_to_10000;
3598+
analyze table t1,t2;
3599+
Table Op Msg_type Msg_text
3600+
test.t1 analyze status Engine-independent statistics collected
3601+
test.t1 analyze status OK
3602+
test.t2 analyze status Engine-independent statistics collected
3603+
test.t2 analyze status Table is already up to date
3604+
# For t2, this must use type=ref, key_len=5 (not type=range, key_len=10)
3605+
explain
3606+
select *
3607+
from t1, t2
3608+
where
3609+
t2.kp1=t1.a and t2.kp1<=100 and t2.kp2<=20;
3610+
id select_type table type possible_keys key key_len ref rows Extra
3611+
1 SIMPLE t1 ALL NULL NULL NULL NULL 100 Using where
3612+
1 SIMPLE t2 ref kp1 kp1 5 test.t1.a 1 Using index condition
3613+
drop table t1,t2;

mysql-test/main/join.test

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1986,3 +1986,32 @@ explain select count(*) from t1, t2 as seq where a=11 and b=seq.seq;
19861986
drop table t1,t2;
19871987

19881988
set @@optimizer_adjust_secondary_key_costs=default;
1989+
1990+
--echo #
1991+
--echo # MDEV-35180: ref_to_range rewrite causes poor query plan
1992+
--echo #
1993+
create table t1 (a int);
1994+
insert into t1 select seq from seq_1_to_100;
1995+
1996+
create table t2 (
1997+
kp1 int,
1998+
kp2 int,
1999+
filler char(100),
2000+
key(kp1, kp2)
2001+
);
2002+
insert into t2
2003+
select
2004+
seq, seq,
2005+
'filler-data'
2006+
from seq_1_to_10000;
2007+
2008+
analyze table t1,t2;
2009+
2010+
--echo # For t2, this must use type=ref, key_len=5 (not type=range, key_len=10)
2011+
explain
2012+
select *
2013+
from t1, t2
2014+
where
2015+
t2.kp1=t1.a and t2.kp1<=100 and t2.kp2<=20;
2016+
2017+
drop table t1,t2;

mysql-test/main/join_cache.result

Lines changed: 6 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -6187,7 +6187,7 @@ explain format=json
61876187
select *
61886188
from t1 a, t3 b
61896189
where
6190-
b.kp1=a.a and
6190+
b.kp1+1=a.a+1 and
61916191
b.kp1 <= 10 and
61926192
b.kp2 <= 10 and
61936193
b.col1 +1 < 33333;
@@ -6197,14 +6197,12 @@ EXPLAIN
61976197
"select_id": 1,
61986198
"table": {
61996199
"table_name": "a",
6200-
"access_type": "range",
6201-
"possible_keys": ["PRIMARY"],
6200+
"access_type": "index",
62026201
"key": "PRIMARY",
62036202
"key_length": "4",
62046203
"used_key_parts": ["a"],
62056204
"rows": 10,
62066205
"filtered": 100,
6207-
"attached_condition": "a.a <= 10",
62086206
"using_index": true
62096207
},
62106208
"block-nl-join": {
@@ -6216,14 +6214,14 @@ EXPLAIN
62166214
"key_length": "10",
62176215
"used_key_parts": ["kp1", "kp2"],
62186216
"rows": 836,
6219-
"filtered": 76.43428802,
6220-
"index_condition": "b.kp2 <= 10",
6221-
"attached_condition": "b.kp2 <= 10 and b.col1 + 1 < 33333"
6217+
"filtered": 100,
6218+
"index_condition": "b.kp1 <= 10 and b.kp2 <= 10",
6219+
"attached_condition": "b.kp1 <= 10 and b.kp2 <= 10 and b.col1 + 1 < 33333"
62226220
},
62236221
"buffer_type": "flat",
62246222
"buffer_size": "54",
62256223
"join_type": "BNL",
6226-
"attached_condition": "b.kp1 = a.a"
6224+
"attached_condition": "b.kp1 + 1 = a.a + 1"
62276225
}
62286226
}
62296227
}

mysql-test/main/join_cache.test

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -4169,7 +4169,7 @@ explain format=json
41694169
select *
41704170
from t1 a, t3 b
41714171
where
4172-
b.kp1=a.a and
4172+
b.kp1+1=a.a+1 and
41734173
b.kp1 <= 10 and
41744174
b.kp2 <= 10 and
41754175
b.col1 +1 < 33333;

sql/sql_select.cc

Lines changed: 31 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -12969,11 +12969,41 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
1296912969

1297012970
used_tables|=current_map;
1297112971

12972+
/*
12973+
Change from using ref access to using quick select on the same index
12974+
if the quick select uses more key parts.
12975+
12976+
There are two cases.
12977+
A. ref access is ref(const). quick select was also constructed using
12978+
equality restrictions that ref used, and so it will scan a subset of
12979+
rows that ref access scans.
12980+
Example: suppose the index is INDEX(kp1, kp2) and the WHERE has:
12981+
12982+
kp1='foo' and kp2 <= 10
12983+
12984+
here, ref access will use kp1='foo' and quick select will use
12985+
(foo) <= (kp1,kp2) <=(foo,10)
12986+
12987+
B. ref access is not constant. In this case, quick select was
12988+
constructed from some other restriction and in general will scan
12989+
totally different set of rows (it maybe larger or smaller).
12990+
Example: for INDEX(kp1, kp2) and the WHERE:
12991+
12992+
kp1 <='foo' and kp1=prev_table.col and kp2 <= 10
12993+
12994+
the ref access will use kp1=prev_table.col, while quick select will
12995+
use (-inf) < (kp1, kp2) <= ('foo',10).
12996+
12997+
Because of the above, we perform the rewrite ONLY when ref is
12998+
ref(const).
12999+
*/
1297213000
if (tab->type == JT_REF && tab->quick &&
1297313001
(((uint) tab->ref.key == tab->quick->index &&
1297413002
tab->ref.key_length < tab->quick->max_used_key_length) ||
1297513003
(!is_hash_join_key_no(tab->ref.key) &&
12976-
tab->table->intersect_keys.is_set(tab->ref.key))))
13004+
tab->table->intersect_keys.is_set(tab->ref.key))) &&
13005+
tab->ref.const_ref_part_map == // (ref-is-const)
13006+
make_prev_keypart_map(tab->ref.key_parts)) // (ref-is-const)
1297713007
{
1297813008
/* Range uses longer key; Use this instead of ref on key */
1297913009
Json_writer_object ref_to_range(thd);

0 commit comments

Comments
 (0)