Skip to content

Commit 6af171f

Browse files
MDEV-36410: Wrong Result with Desc Primary Key in Index
If a table had a primary_key index, non_primary_key index, and an extended index with primary key in desc order, then the query with where clause predicates containing these index fields was picking an index_merge plan which was causing a wrong result. The plan shouldn't have contained index_merge in the first place, because the rows produced by one index have rows ordered by rowid in ascending order, and the rows coming from the other index were in a different order. The solution is to not produce index_merge plan in such scenarios. is_key_scan_ror() would now return false, for non_primary_key indexes if any primary key part with a reverse sort is present in them.
1 parent 7f77041 commit 6af171f

File tree

3 files changed

+220
-6
lines changed

3 files changed

+220
-6
lines changed
Lines changed: 102 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,102 @@
1+
2+
# MDEV-36410 wrong result with index_merge on indexes having descending primary key
3+
#
4+
set optimizer_trace='enabled=on';
5+
SET @save_sort_buffer_size=@@sort_buffer_size;
6+
SET SESSION sort_buffer_size = 1024*16;
7+
CREATE TABLE t1 (
8+
id bigint(20) NOT NULL,
9+
title varchar(255) NOT NULL,
10+
status tinyint(4) DEFAULT 0,
11+
country_code varchar(5) DEFAULT NULL,
12+
PRIMARY KEY (id),
13+
KEY idx_status (status),
14+
KEY idx_country_code_status_id (country_code,status,id DESC)
15+
) ENGINE=InnoDB;
16+
INSERT INTO t1(id,title,status,country_code)
17+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
18+
# This must not use index_merge:
19+
EXPLAIN
20+
SELECT * FROM t1 WHERE country_code ='C1' and `status` =1;
21+
id select_type table type possible_keys key key_len ref rows Extra
22+
1 SIMPLE t1 ref idx_status,idx_country_code_status_id idx_status 2 const 50 Using where
23+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
24+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
25+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
26+
INDEXES
27+
[
28+
"idx_status",
29+
"idx_country_code_status_id"
30+
]
31+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
32+
ROR
33+
[
34+
true,
35+
false
36+
]
37+
DROP table t1;
38+
# Now, try with indexes using ASC ordering and PK using DESC
39+
CREATE TABLE t1 (
40+
id bigint(20) NOT NULL,
41+
title varchar(255) NOT NULL,
42+
status tinyint(4) DEFAULT 0,
43+
country_code varchar(5) DEFAULT NULL,
44+
PRIMARY KEY (id DESC),
45+
KEY idx_status (status),
46+
KEY idx_country_code_status_id (country_code,status,id)
47+
) ENGINE=InnoDB;
48+
INSERT INTO t1(id,title,status,country_code)
49+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
50+
# Must not use index_merge:
51+
EXPLAIN
52+
SELECT * FROM t1 WHERE country_code ='C1' and status = 1;
53+
id select_type table type possible_keys key key_len ref rows Extra
54+
1 SIMPLE t1 ref idx_status,idx_country_code_status_id idx_status 2 const 50 Using where
55+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
56+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
57+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
58+
INDEXES
59+
[
60+
"idx_status",
61+
"idx_country_code_status_id"
62+
]
63+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
64+
ROR
65+
[
66+
true,
67+
false
68+
]
69+
DROP TABLE t1;
70+
# Now, try with indexes using DESC ordering and PK using DESC
71+
CREATE TABLE t1 (
72+
id bigint(20) NOT NULL,
73+
title varchar(255) NOT NULL,
74+
status tinyint(4) DEFAULT 0,
75+
country_code varchar(5) DEFAULT NULL,
76+
PRIMARY KEY (id DESC),
77+
KEY idx_status (status),
78+
KEY idx_country_code_status_id (country_code,status,id DESC)
79+
) ENGINE=InnoDB;
80+
INSERT INTO t1(id,title,status,country_code)
81+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
82+
# Must not use index_merge:
83+
EXPLAIN
84+
SELECT * FROM t1 WHERE country_code ='C1' and status = 1;
85+
id select_type table type possible_keys key key_len ref rows Extra
86+
1 SIMPLE t1 ref idx_status,idx_country_code_status_id idx_status 2 const 50 Using where
87+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
88+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
89+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
90+
INDEXES
91+
[
92+
"idx_status",
93+
"idx_country_code_status_id"
94+
]
95+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
96+
ROR
97+
[
98+
true,
99+
false
100+
]
101+
DROP TABLE t1;
102+
SET sort_buffer_size= @save_sort_buffer_size;
Lines changed: 90 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,90 @@
1+
--source include/have_innodb.inc
2+
--source include/have_sequence.inc
3+
--source include/not_embedded.inc
4+
5+
--echo
6+
--echo # MDEV-36410 wrong result with index_merge on indexes having descending primary key
7+
--echo #
8+
9+
set optimizer_trace='enabled=on';
10+
SET @save_sort_buffer_size=@@sort_buffer_size;
11+
SET SESSION sort_buffer_size = 1024*16;
12+
13+
CREATE TABLE t1 (
14+
id bigint(20) NOT NULL,
15+
title varchar(255) NOT NULL,
16+
status tinyint(4) DEFAULT 0,
17+
country_code varchar(5) DEFAULT NULL,
18+
PRIMARY KEY (id),
19+
KEY idx_status (status),
20+
KEY idx_country_code_status_id (country_code,status,id DESC)
21+
) ENGINE=InnoDB;
22+
23+
INSERT INTO t1(id,title,status,country_code)
24+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
25+
26+
--echo # This must not use index_merge:
27+
EXPLAIN
28+
SELECT * FROM t1 WHERE country_code ='C1' and `status` =1;
29+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
30+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
31+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
32+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
33+
34+
#select JSON_DETAILED(JSON_EXTRACT(trace, '$**.range_scan_alternatives[*].index')) AS JS from INFORMATION_SCHEMA.OPTIMIZER_TRACE;
35+
36+
DROP table t1;
37+
38+
--echo # Now, try with indexes using ASC ordering and PK using DESC
39+
CREATE TABLE t1 (
40+
id bigint(20) NOT NULL,
41+
title varchar(255) NOT NULL,
42+
status tinyint(4) DEFAULT 0,
43+
country_code varchar(5) DEFAULT NULL,
44+
PRIMARY KEY (id DESC),
45+
KEY idx_status (status),
46+
KEY idx_country_code_status_id (country_code,status,id)
47+
) ENGINE=InnoDB;
48+
49+
INSERT INTO t1(id,title,status,country_code)
50+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
51+
52+
--echo # Must not use index_merge:
53+
EXPLAIN
54+
SELECT * FROM t1 WHERE country_code ='C1' and status = 1;
55+
56+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
57+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
58+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
59+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
60+
61+
DROP TABLE t1;
62+
63+
--echo # Now, try with indexes using DESC ordering and PK using DESC
64+
CREATE TABLE t1 (
65+
id bigint(20) NOT NULL,
66+
title varchar(255) NOT NULL,
67+
status tinyint(4) DEFAULT 0,
68+
country_code varchar(5) DEFAULT NULL,
69+
PRIMARY KEY (id DESC),
70+
KEY idx_status (status),
71+
KEY idx_country_code_status_id (country_code,status,id DESC)
72+
) ENGINE=InnoDB;
73+
74+
INSERT INTO t1(id,title,status,country_code)
75+
SELECT seq, CONCAT('abc', seq), seq%10, CONCAT('C', seq%5) FROM seq_1_to_500;
76+
77+
--echo # Must not use index_merge:
78+
EXPLAIN
79+
SELECT * FROM t1 WHERE country_code ='C1' and status = 1;
80+
81+
set @trace= (select JSON_EXTRACT(trace, '$**.range_scan_alternatives[*]')
82+
from INFORMATION_SCHEMA.OPTIMIZER_TRACE);
83+
select json_detailed(json_extract(@trace, '$[*].index')) as INDEXES;
84+
select json_detailed(json_extract(@trace, '$[*].rowid_ordered')) as ROR;
85+
86+
DROP TABLE t1;
87+
88+
SET sort_buffer_size= @save_sort_buffer_size;
89+
90+

sql/opt_range.cc

Lines changed: 28 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -11931,22 +11931,44 @@ static bool is_key_scan_ror(PARAM *param, uint keynr, uint8 nparts)
1193111931
return FALSE;
1193211932
}
1193311933

11934-
/*
11935-
If there are equalities for all key parts, it is a ROR scan. If there are
11936-
equalities all keyparts and even some of key parts from "Extended Key"
11937-
index suffix, it is a ROR-scan, too.
11938-
*/
1193911934
if (key_part >= key_part_end)
1194011935
return TRUE;
1194111936

11942-
key_part= table_key->key_part + nparts;
1194311937
pk_number= param->table->s->primary_key;
1194411938
if (!param->table->file->pk_is_clustering_key(pk_number))
1194511939
return FALSE;
1194611940

11941+
if (keynr == pk_number)
11942+
return TRUE; /* Scan on clustered PK is always ROR */
11943+
11944+
1194711945
KEY_PART_INFO *pk_part= param->table->key_info[pk_number].key_part;
1194811946
KEY_PART_INFO *pk_part_end= pk_part +
1194911947
param->table->key_info[pk_number].user_defined_key_parts;
11948+
/*
11949+
Check for columns indexed with DESC.
11950+
If a column is present in both Secondary Key and Primary Key and either of
11951+
indexes include it with DESC, then the scan is not a ROR scan.
11952+
*/
11953+
for (; key_part != key_part_end; ++key_part)
11954+
{
11955+
pk_part= param->table->key_info[pk_number].key_part;
11956+
for (; pk_part != pk_part_end; ++pk_part)
11957+
{
11958+
if (key_part->fieldnr == pk_part->fieldnr &&
11959+
(MY_TEST(key_part->key_part_flag & HA_REVERSE_SORT) ||
11960+
MY_TEST(pk_part->key_part_flag & HA_REVERSE_SORT)))
11961+
return FALSE;
11962+
}
11963+
}
11964+
11965+
/*
11966+
If there are equalities for all key parts, it is a ROR scan. If there are
11967+
equalities all keyparts and even some of key parts from "Extended Key"
11968+
index suffix, it is a ROR-scan, too.
11969+
*/
11970+
key_part= table_key->key_part + nparts;
11971+
pk_part= param->table->key_info[pk_number].key_part;
1195011972
for (;(key_part!=key_part_end) && (pk_part != pk_part_end);
1195111973
++key_part, ++pk_part)
1195211974
{

0 commit comments

Comments
 (0)