Skip to content

Commit cb37c55

Browse files
author
Jan Lindström
committed
MDEV-6929: Port Facebook Prefix Index Queries Optimization
Merge Facebook commit 154c579b828a60722a7d9477fc61868c07453d08 and e8f0052f9b112dc786bf9b957ed5b16a5749f7fd authored by Steaphan Greene from https://github.com/facebook/mysql-5.6 Optimize prefix index queries to skip cluster index lookup when possible. Currently InnoDB will always fetch the clustered index (primary key index) for all prefix columns in an index, even when the value of a particular record is smaller than the prefix length. This change optimizes that case to use the record from the secondary index and avoid the extra lookup. Also adds two status vars that track how effective this is: innodb_secondary_index_triggered_cluster_reads: Times secondary index lookup triggered cluster lookup. innodb_secondary_index_triggered_cluster_reads_avoided: Times prefix optimization avoided triggering cluster lookup.
1 parent 3c2c036 commit cb37c55

37 files changed

+871
-52
lines changed
Lines changed: 102 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,102 @@
1+
drop table if exists prefixinno;
2+
set global innodb_prefix_index_cluster_optimization = ON;
3+
show variables like 'innodb_prefix_index_cluster_optimization';
4+
Variable_name Value
5+
innodb_prefix_index_cluster_optimization ON
6+
# Create a table with a large varchar field that we index the prefix
7+
# of and ensure we only trigger cluster lookups when we expect it.
8+
create table prefixinno (
9+
id int not null,
10+
fake_id int not null,
11+
bigfield varchar(4096),
12+
primary key(id),
13+
index bigfield_idx (bigfield(32)),
14+
index fake_id_bigfield_prefix (fake_id, bigfield(32))
15+
) engine=innodb;
16+
insert into prefixinno values (1, 1001, repeat('a', 1)),
17+
(8, 1008, repeat('b', 8)),
18+
(24, 1024, repeat('c', 24)),
19+
(31, 1031, repeat('d', 31)),
20+
(32, 1032, repeat('x', 32)),
21+
(33, 1033, repeat('y', 33)),
22+
(128, 1128, repeat('z', 128));
23+
select * from prefixinno;
24+
id fake_id bigfield
25+
1 1001 a
26+
8 1008 bbbbbbbb
27+
24 1024 cccccccccccccccccccccccc
28+
31 1031 ddddddddddddddddddddddddddddddd
29+
32 1032 xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx
30+
33 1033 yyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyy
31+
128 1128 zzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzz
32+
# Baseline sanity check: 0, 0.
33+
no-op query
34+
no-op query
35+
cluster_lookups_matched
36+
1
37+
cluster_lookups_avoided_matched
38+
1
39+
# Eligible for optimization.
40+
id bigfield
41+
31 ddddddddddddddddddddddddddddddd
42+
cluster_lookups_matched
43+
1
44+
cluster_lookups_avoided_matched
45+
1
46+
# Eligible for optimization, access via fake_id only.
47+
id bigfield
48+
31 ddddddddddddddddddddddddddddddd
49+
cluster_lookups_matched
50+
1
51+
cluster_lookups_avoided_matched
52+
1
53+
# Not eligible for optimization, access via fake_id of big row.
54+
id bigfield
55+
33 yyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyy
56+
cluster_lookups_matched
57+
1
58+
cluster_lookups_avoided_matched
59+
1
60+
# Not eligible for optimization.
61+
id bigfield
62+
32 xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx
63+
cluster_lookups_matched
64+
1
65+
cluster_lookups_avoided_matched
66+
1
67+
# Not eligible for optimization.
68+
id bigfield
69+
33 yyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyy
70+
cluster_lookups_matched
71+
1
72+
cluster_lookups_avoided_matched
73+
1
74+
# Eligible, should not increment lookup counter.
75+
id bigfield
76+
8 bbbbbbbb
77+
cluster_lookups_matched
78+
1
79+
cluster_lookups_avoided_matched
80+
1
81+
# Eligible, should not increment lookup counter.
82+
id bigfield
83+
24 cccccccccccccccccccccccc
84+
cluster_lookups_matched
85+
1
86+
cluster_lookups_avoided_matched
87+
1
88+
# Should increment lookup counter.
89+
id bigfield
90+
128 zzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzz
91+
cluster_lookups_matched
92+
1
93+
cluster_lookups_avoided_matched
94+
1
95+
# Disable optimization, confirm we still increment counter.
96+
id bigfield
97+
33 yyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyyy
98+
cluster_lookups_matched
99+
1
100+
cluster_lookups_avoided_matched
101+
1
102+
# make test suite happy by cleaning up our mess

mysql-test/suite/sys_vars/r/innodb_monitor_disable_basic.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -40,6 +40,8 @@ buffer_pages_written disabled
4040
buffer_index_pages_written disabled
4141
buffer_non_index_pages_written disabled
4242
buffer_pages_read disabled
43+
buffer_index_sec_rec_cluster_reads disabled
44+
buffer_index_sec_rec_cluster_reads_avoided disabled
4345
buffer_data_reads disabled
4446
buffer_data_written disabled
4547
buffer_flush_batch_scanned disabled

mysql-test/suite/sys_vars/r/innodb_monitor_enable_basic.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -40,6 +40,8 @@ buffer_pages_written disabled
4040
buffer_index_pages_written disabled
4141
buffer_non_index_pages_written disabled
4242
buffer_pages_read disabled
43+
buffer_index_sec_rec_cluster_reads disabled
44+
buffer_index_sec_rec_cluster_reads_avoided disabled
4345
buffer_data_reads disabled
4446
buffer_data_written disabled
4547
buffer_flush_batch_scanned disabled

mysql-test/suite/sys_vars/r/innodb_monitor_reset_all_basic.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -40,6 +40,8 @@ buffer_pages_written disabled
4040
buffer_index_pages_written disabled
4141
buffer_non_index_pages_written disabled
4242
buffer_pages_read disabled
43+
buffer_index_sec_rec_cluster_reads disabled
44+
buffer_index_sec_rec_cluster_reads_avoided disabled
4345
buffer_data_reads disabled
4446
buffer_data_written disabled
4547
buffer_flush_batch_scanned disabled

mysql-test/suite/sys_vars/r/innodb_monitor_reset_basic.result

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -40,6 +40,8 @@ buffer_pages_written disabled
4040
buffer_index_pages_written disabled
4141
buffer_non_index_pages_written disabled
4242
buffer_pages_read disabled
43+
buffer_index_sec_rec_cluster_reads disabled
44+
buffer_index_sec_rec_cluster_reads_avoided disabled
4345
buffer_data_reads disabled
4446
buffer_data_written disabled
4547
buffer_flush_batch_scanned disabled
Lines changed: 122 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,122 @@
1+
SET @start_global_value = @@global.innodb_prefix_index_cluster_optimization;
2+
SELECT @start_global_value;
3+
@start_global_value
4+
0
5+
#
6+
# exists as global only
7+
#
8+
Valid values are 'ON' and 'OFF'
9+
select @@global.innodb_prefix_index_cluster_optimization in (0, 1);
10+
@@global.innodb_prefix_index_cluster_optimization in (0, 1)
11+
1
12+
select @@global.innodb_prefix_index_cluster_optimization;
13+
@@global.innodb_prefix_index_cluster_optimization
14+
0
15+
select @@session.innodb_prefix_index_cluster_optimization;
16+
ERROR HY000: Variable 'innodb_prefix_index_cluster_optimization' is a GLOBAL variable
17+
show global variables like 'innodb_prefix_index_cluster_optimization';
18+
Variable_name Value
19+
innodb_prefix_index_cluster_optimization OFF
20+
show session variables like 'innodb_prefix_index_cluster_optimization';
21+
Variable_name Value
22+
innodb_prefix_index_cluster_optimization OFF
23+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
24+
VARIABLE_NAME VARIABLE_VALUE
25+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
26+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
27+
VARIABLE_NAME VARIABLE_VALUE
28+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
29+
#
30+
# show that it's writable
31+
#
32+
set global innodb_prefix_index_cluster_optimization = 'OFF';
33+
select @@global.innodb_prefix_index_cluster_optimization;
34+
@@global.innodb_prefix_index_cluster_optimization
35+
0
36+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
37+
VARIABLE_NAME VARIABLE_VALUE
38+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
39+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
40+
VARIABLE_NAME VARIABLE_VALUE
41+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
42+
set @@global.innodb_prefix_index_cluster_optimization = 'ON';
43+
select @@global.innodb_prefix_index_cluster_optimization;
44+
@@global.innodb_prefix_index_cluster_optimization
45+
1
46+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
47+
VARIABLE_NAME VARIABLE_VALUE
48+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
49+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
50+
VARIABLE_NAME VARIABLE_VALUE
51+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
52+
set global innodb_prefix_index_cluster_optimization = 0;
53+
select @@global.innodb_prefix_index_cluster_optimization;
54+
@@global.innodb_prefix_index_cluster_optimization
55+
0
56+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
57+
VARIABLE_NAME VARIABLE_VALUE
58+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
59+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
60+
VARIABLE_NAME VARIABLE_VALUE
61+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION OFF
62+
set @@global.innodb_prefix_index_cluster_optimization = 1;
63+
select @@global.innodb_prefix_index_cluster_optimization;
64+
@@global.innodb_prefix_index_cluster_optimization
65+
1
66+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
67+
VARIABLE_NAME VARIABLE_VALUE
68+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
69+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
70+
VARIABLE_NAME VARIABLE_VALUE
71+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
72+
set session innodb_prefix_index_cluster_optimization = 'OFF';
73+
ERROR HY000: Variable 'innodb_prefix_index_cluster_optimization' is a GLOBAL variable and should be set with SET GLOBAL
74+
select @@global.innodb_prefix_index_cluster_optimization;
75+
@@global.innodb_prefix_index_cluster_optimization
76+
1
77+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
78+
VARIABLE_NAME VARIABLE_VALUE
79+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
80+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
81+
VARIABLE_NAME VARIABLE_VALUE
82+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
83+
set @@session.innodb_prefix_index_cluster_optimization = 'ON';
84+
ERROR HY000: Variable 'innodb_prefix_index_cluster_optimization' is a GLOBAL variable and should be set with SET GLOBAL
85+
select @@global.innodb_prefix_index_cluster_optimization;
86+
@@global.innodb_prefix_index_cluster_optimization
87+
1
88+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
89+
VARIABLE_NAME VARIABLE_VALUE
90+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
91+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
92+
VARIABLE_NAME VARIABLE_VALUE
93+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
94+
#
95+
# incorrect types
96+
#
97+
set global innodb_prefix_index_cluster_optimization = 1.1;
98+
ERROR 42000: Incorrect argument type to variable 'innodb_prefix_index_cluster_optimization'
99+
set global innodb_prefix_index_cluster_optimization = 1e1;
100+
ERROR 42000: Incorrect argument type to variable 'innodb_prefix_index_cluster_optimization'
101+
set global innodb_prefix_index_cluster_optimization = 2;
102+
ERROR 42000: Variable 'innodb_prefix_index_cluster_optimization' can't be set to the value of '2'
103+
set global innodb_prefix_index_cluster_optimization = -3;
104+
ERROR 42000: Variable 'innodb_prefix_index_cluster_optimization' can't be set to the value of '-3'
105+
select @@global.innodb_prefix_index_cluster_optimization;
106+
@@global.innodb_prefix_index_cluster_optimization
107+
1
108+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
109+
VARIABLE_NAME VARIABLE_VALUE
110+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
111+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
112+
VARIABLE_NAME VARIABLE_VALUE
113+
INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION ON
114+
set global innodb_prefix_index_cluster_optimization = 'AUTO';
115+
ERROR 42000: Variable 'innodb_prefix_index_cluster_optimization' can't be set to the value of 'AUTO'
116+
#
117+
# Cleanup
118+
#
119+
SET @@global.innodb_prefix_index_cluster_optimization = @start_global_value;
120+
SELECT @@global.innodb_prefix_index_cluster_optimization;
121+
@@global.innodb_prefix_index_cluster_optimization
122+
0

mysql-test/suite/sys_vars/r/sysvars_innodb.result

Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1461,6 +1461,20 @@ NUMERIC_BLOCK_SIZE 0
14611461
ENUM_VALUE_LIST NULL
14621462
READ_ONLY YES
14631463
COMMAND_LINE_ARGUMENT OPTIONAL
1464+
VARIABLE_NAME INNODB_PREFIX_INDEX_CLUSTER_OPTIMIZATION
1465+
SESSION_VALUE NULL
1466+
GLOBAL_VALUE OFF
1467+
GLOBAL_VALUE_ORIGIN COMPILE-TIME
1468+
DEFAULT_VALUE OFF
1469+
VARIABLE_SCOPE GLOBAL
1470+
VARIABLE_TYPE BOOLEAN
1471+
VARIABLE_COMMENT Enable prefix optimization to sometimes avoid cluster index lookups.
1472+
NUMERIC_MIN_VALUE NULL
1473+
NUMERIC_MAX_VALUE NULL
1474+
NUMERIC_BLOCK_SIZE NULL
1475+
ENUM_VALUE_LIST NULL
1476+
READ_ONLY NO
1477+
COMMAND_LINE_ARGUMENT OPTIONAL
14641478
VARIABLE_NAME INNODB_PRINT_ALL_DEADLOCKS
14651479
SESSION_VALUE NULL
14661480
GLOBAL_VALUE OFF
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
--source include/have_innodb.inc
2+
3+
SET @start_global_value = @@global.innodb_prefix_index_cluster_optimization;
4+
SELECT @start_global_value;
5+
6+
--echo #
7+
--echo # exists as global only
8+
--echo #
9+
10+
--echo Valid values are 'ON' and 'OFF'
11+
select @@global.innodb_prefix_index_cluster_optimization in (0, 1);
12+
select @@global.innodb_prefix_index_cluster_optimization;
13+
--error ER_INCORRECT_GLOBAL_LOCAL_VAR
14+
select @@session.innodb_prefix_index_cluster_optimization;
15+
show global variables like 'innodb_prefix_index_cluster_optimization';
16+
show session variables like 'innodb_prefix_index_cluster_optimization';
17+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
18+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
19+
20+
--echo #
21+
--echo # show that it's writable
22+
--echo #
23+
24+
set global innodb_prefix_index_cluster_optimization = 'OFF';
25+
select @@global.innodb_prefix_index_cluster_optimization;
26+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
27+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
28+
set @@global.innodb_prefix_index_cluster_optimization = 'ON';
29+
select @@global.innodb_prefix_index_cluster_optimization;
30+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
31+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
32+
set global innodb_prefix_index_cluster_optimization = 0;
33+
select @@global.innodb_prefix_index_cluster_optimization;
34+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
35+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
36+
set @@global.innodb_prefix_index_cluster_optimization = 1;
37+
select @@global.innodb_prefix_index_cluster_optimization;
38+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
39+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
40+
41+
--error ER_GLOBAL_VARIABLE
42+
set session innodb_prefix_index_cluster_optimization = 'OFF';
43+
select @@global.innodb_prefix_index_cluster_optimization;
44+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
45+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
46+
47+
--error ER_GLOBAL_VARIABLE
48+
set @@session.innodb_prefix_index_cluster_optimization = 'ON';
49+
select @@global.innodb_prefix_index_cluster_optimization;
50+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
51+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
52+
53+
--echo #
54+
--echo # incorrect types
55+
--echo #
56+
57+
--error ER_WRONG_TYPE_FOR_VAR
58+
set global innodb_prefix_index_cluster_optimization = 1.1;
59+
--error ER_WRONG_TYPE_FOR_VAR
60+
set global innodb_prefix_index_cluster_optimization = 1e1;
61+
--error ER_WRONG_VALUE_FOR_VAR
62+
set global innodb_prefix_index_cluster_optimization = 2;
63+
--error ER_WRONG_VALUE_FOR_VAR
64+
set global innodb_prefix_index_cluster_optimization = -3;
65+
select @@global.innodb_prefix_index_cluster_optimization;
66+
select * from information_schema.global_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
67+
select * from information_schema.session_variables where variable_name = 'innodb_prefix_index_cluster_optimization';
68+
--error ER_WRONG_VALUE_FOR_VAR
69+
set global innodb_prefix_index_cluster_optimization = 'AUTO';
70+
71+
--echo #
72+
--echo # Cleanup
73+
--echo #
74+
75+
SET @@global.innodb_prefix_index_cluster_optimization = @start_global_value;
76+
SELECT @@global.innodb_prefix_index_cluster_optimization;

0 commit comments

Comments
 (0)