Skip to content

Commit b01ff6a

Browse files
lthfacebook-github-bot
authored andcommitted
Add variable to force range plans if force index is used
Summary: Currently, when force index is used, full table scans are highly penalized, but it is still possible to do a full index scan which is expensive. In many cases, we only use force index when we know there is better way to traverse the index, and not necessarily because we want a full index scan. To address these cases, add a session variable called optimizer_force_index_for_range, which when turned on, will try to search for a 'range' plan before falling back to an index plan. Reviewed By: hermanlee Differential Revision: D7526748 fbshipit-source-id: 4a4641b
1 parent bcb7d9c commit b01ff6a

9 files changed

+333
-1
lines changed

mysql-test/r/mysqld--help-notwin-profiling.result

+4
Original file line numberDiff line numberDiff line change
@@ -719,6 +719,9 @@ The following options may be given as the first argument:
719719
value is 0 then mysqld will reserve max_connections*5 or
720720
max_connections + table_open_cache*2 (whichever is
721721
larger) number of file descriptors
722+
--optimizer-force-index-for-range
723+
If enabled, FORCE INDEX will also try to force a range
724+
plan.
722725
--optimizer-low-limit-heuristic
723726
Enable low limit heuristic.
724727
(Defaults to on; use --skip-optimizer-low-limit-heuristic to disable.)
@@ -2030,6 +2033,7 @@ old FALSE
20302033
old-alter-table FALSE
20312034
old-passwords 0
20322035
old-style-user-limits FALSE
2036+
optimizer-force-index-for-range FALSE
20332037
optimizer-low-limit-heuristic TRUE
20342038
optimizer-prune-level 1
20352039
optimizer-search-depth 62

mysql-test/r/mysqld--help-notwin.result

+4
Original file line numberDiff line numberDiff line change
@@ -719,6 +719,9 @@ The following options may be given as the first argument:
719719
value is 0 then mysqld will reserve max_connections*5 or
720720
max_connections + table_open_cache*2 (whichever is
721721
larger) number of file descriptors
722+
--optimizer-force-index-for-range
723+
If enabled, FORCE INDEX will also try to force a range
724+
plan.
722725
--optimizer-low-limit-heuristic
723726
Enable low limit heuristic.
724727
(Defaults to on; use --skip-optimizer-low-limit-heuristic to disable.)
@@ -2028,6 +2031,7 @@ old FALSE
20282031
old-alter-table FALSE
20292032
old-passwords 0
20302033
old-style-user-limits FALSE
2034+
optimizer-force-index-for-range FALSE
20312035
optimizer-low-limit-heuristic TRUE
20322036
optimizer-prune-level 1
20332037
optimizer-search-depth 62
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,62 @@
1+
set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range;
2+
create table t (i int, j int, primary key (i, j));
3+
insert into t values (1, 1);
4+
insert into t values (1, 2);
5+
insert into t values (2, 1);
6+
insert into t values (2, 2);
7+
insert into t values (3, 1);
8+
insert into t values (3, 2);
9+
# Test range plans
10+
set optimizer_force_index_for_range = on;
11+
explain select i from t where i in (1, 2, 3) and j in (1, 2);
12+
id select_type table type possible_keys key key_len ref rows Extra
13+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
14+
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2);
15+
id select_type table type possible_keys key key_len ref rows Extra
16+
1 SIMPLE t range PRIMARY PRIMARY 8 NULL # Using where; Using index
17+
set optimizer_force_index_for_range = off;
18+
explain select i from t where i in (1, 2, 3) and j in (1, 2);
19+
id select_type table type possible_keys key key_len ref rows Extra
20+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
21+
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2);
22+
id select_type table type possible_keys key key_len ref rows Extra
23+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
24+
# Test group-by plans.
25+
set optimizer_force_index_for_range = on;
26+
explain select distinct i from t;
27+
id select_type table type possible_keys key key_len ref rows Extra
28+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index
29+
explain select distinct i from t force index (primary);
30+
id select_type table type possible_keys key key_len ref rows Extra
31+
1 SIMPLE t range PRIMARY PRIMARY 4 NULL # Using index for group-by
32+
set optimizer_force_index_for_range = off;
33+
explain select distinct i from t;
34+
id select_type table type possible_keys key key_len ref rows Extra
35+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index
36+
explain select distinct i from t force index (primary);
37+
id select_type table type possible_keys key key_len ref rows Extra
38+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index
39+
# Test skip-scan plans.
40+
set optimizer_switch = 'skip_scan=on';
41+
set optimizer_force_index_for_range = on;
42+
explain select i from t where j > 1;
43+
id select_type table type possible_keys key key_len ref rows Extra
44+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
45+
explain select i from t force index (primary) where j > 1;
46+
id select_type table type possible_keys key key_len ref rows Extra
47+
1 SIMPLE t range PRIMARY PRIMARY 8 NULL # Using where; Using index for skip scan
48+
set optimizer_force_index_for_range = off;
49+
explain select i from t where j > 1;
50+
id select_type table type possible_keys key key_len ref rows Extra
51+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
52+
explain select i from t force index (primary) where j > 1;
53+
id select_type table type possible_keys key key_len ref rows Extra
54+
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index
55+
set optimizer_switch = 'skip_scan=off';
56+
# Test that in absence of range plan, index is used.
57+
set optimizer_force_index_for_range = on;
58+
explain select i from t force index (primary) where j > 1;
59+
id select_type table type possible_keys key key_len ref rows Extra
60+
1 SIMPLE t index NULL PRIMARY 8 NULL # Using where; Using index
61+
drop table t;
62+
set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,93 @@
1+
SET @session_start_value = @@session.optimizer_force_index_for_range;
2+
SELECT @session_start_value;
3+
@session_start_value
4+
0
5+
SET @global_start_value = @@global.optimizer_force_index_for_range;
6+
SELECT @global_start_value;
7+
@global_start_value
8+
0
9+
SET @@session.optimizer_force_index_for_range = 0;
10+
SET @@session.optimizer_force_index_for_range = DEFAULT;
11+
SELECT @@session.optimizer_force_index_for_range;
12+
@@session.optimizer_force_index_for_range
13+
0
14+
SET @@session.optimizer_force_index_for_range = 1;
15+
SET @@session.optimizer_force_index_for_range = DEFAULT;
16+
SELECT @@session.optimizer_force_index_for_range;
17+
@@session.optimizer_force_index_for_range
18+
0
19+
SET optimizer_force_index_for_range = 1;
20+
SELECT @@optimizer_force_index_for_range;
21+
@@optimizer_force_index_for_range
22+
1
23+
SELECT session.optimizer_force_index_for_range;
24+
ERROR 42S02: Unknown table 'session' in field list
25+
SELECT local.optimizer_force_index_for_range;
26+
ERROR 42S02: Unknown table 'local' in field list
27+
SET session optimizer_force_index_for_range = 0;
28+
SELECT @@session.optimizer_force_index_for_range;
29+
@@session.optimizer_force_index_for_range
30+
0
31+
SET @@session.optimizer_force_index_for_range = 0;
32+
SELECT @@session.optimizer_force_index_for_range;
33+
@@session.optimizer_force_index_for_range
34+
0
35+
SET @@session.optimizer_force_index_for_range = 1;
36+
SELECT @@session.optimizer_force_index_for_range;
37+
@@session.optimizer_force_index_for_range
38+
1
39+
SET @@session.optimizer_force_index_for_range = -1;
40+
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of '-1'
41+
SET @@session.optimizer_force_index_for_range = 2;
42+
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of '2'
43+
SET @@session.optimizer_force_index_for_range = "T";
44+
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'T'
45+
SET @@session.optimizer_force_index_for_range = "Y";
46+
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'Y'
47+
SET @@session.optimizer_force_index_for_range = NO;
48+
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'NO'
49+
SET @@global.optimizer_force_index_for_range = 1;
50+
SELECT @@global.optimizer_force_index_for_range;
51+
@@global.optimizer_force_index_for_range
52+
1
53+
SET @@global.optimizer_force_index_for_range = 0;
54+
SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_force_index_for_range';
55+
count(VARIABLE_VALUE)
56+
1
57+
SELECT IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE
58+
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
59+
WHERE VARIABLE_NAME='optimizer_force_index_for_range';
60+
IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE
61+
1
62+
SELECT @@session.optimizer_force_index_for_range;
63+
@@session.optimizer_force_index_for_range
64+
1
65+
SELECT VARIABLE_VALUE
66+
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
67+
WHERE VARIABLE_NAME='optimizer_force_index_for_range';
68+
VARIABLE_VALUE
69+
ON
70+
SET @@session.optimizer_force_index_for_range = OFF;
71+
SELECT @@session.optimizer_force_index_for_range;
72+
@@session.optimizer_force_index_for_range
73+
0
74+
SET @@session.optimizer_force_index_for_range = ON;
75+
SELECT @@session.optimizer_force_index_for_range;
76+
@@session.optimizer_force_index_for_range
77+
1
78+
SET @@session.optimizer_force_index_for_range = TRUE;
79+
SELECT @@session.optimizer_force_index_for_range;
80+
@@session.optimizer_force_index_for_range
81+
1
82+
SET @@session.optimizer_force_index_for_range = FALSE;
83+
SELECT @@session.optimizer_force_index_for_range;
84+
@@session.optimizer_force_index_for_range
85+
0
86+
SET @@session.optimizer_force_index_for_range = @session_start_value;
87+
SELECT @@session.optimizer_force_index_for_range;
88+
@@session.optimizer_force_index_for_range
89+
0
90+
SET @@global.optimizer_force_index_for_range = @global_start_value;
91+
SELECT @@global.optimizer_force_index_for_range;
92+
@@global.optimizer_force_index_for_range
93+
0
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,102 @@
1+
--source include/load_sysvars.inc
2+
3+
4+
# Saving initial value of optimizer_force_index_for_range in a temporary variable
5+
6+
SET @session_start_value = @@session.optimizer_force_index_for_range;
7+
SELECT @session_start_value;
8+
SET @global_start_value = @@global.optimizer_force_index_for_range;
9+
SELECT @global_start_value;
10+
11+
# Display the DEFAULT value of optimizer_force_index_for_range
12+
13+
SET @@session.optimizer_force_index_for_range = 0;
14+
SET @@session.optimizer_force_index_for_range = DEFAULT;
15+
SELECT @@session.optimizer_force_index_for_range;
16+
17+
SET @@session.optimizer_force_index_for_range = 1;
18+
SET @@session.optimizer_force_index_for_range = DEFAULT;
19+
SELECT @@session.optimizer_force_index_for_range;
20+
21+
22+
# Check if optimizer_force_index_for_range can be accessed with and without @@ sign
23+
24+
SET optimizer_force_index_for_range = 1;
25+
SELECT @@optimizer_force_index_for_range;
26+
27+
--Error ER_UNKNOWN_TABLE
28+
SELECT session.optimizer_force_index_for_range;
29+
30+
--Error ER_UNKNOWN_TABLE
31+
SELECT local.optimizer_force_index_for_range;
32+
33+
SET session optimizer_force_index_for_range = 0;
34+
SELECT @@session.optimizer_force_index_for_range;
35+
36+
# change the value of optimizer_force_index_for_range to a valid value
37+
38+
SET @@session.optimizer_force_index_for_range = 0;
39+
SELECT @@session.optimizer_force_index_for_range;
40+
SET @@session.optimizer_force_index_for_range = 1;
41+
SELECT @@session.optimizer_force_index_for_range;
42+
43+
44+
# Change the value of optimizer_force_index_for_range to invalid value
45+
46+
--Error ER_WRONG_VALUE_FOR_VAR
47+
SET @@session.optimizer_force_index_for_range = -1;
48+
--Error ER_WRONG_VALUE_FOR_VAR
49+
SET @@session.optimizer_force_index_for_range = 2;
50+
--Error ER_WRONG_VALUE_FOR_VAR
51+
SET @@session.optimizer_force_index_for_range = "T";
52+
--Error ER_WRONG_VALUE_FOR_VAR
53+
SET @@session.optimizer_force_index_for_range = "Y";
54+
--Error ER_WRONG_VALUE_FOR_VAR
55+
SET @@session.optimizer_force_index_for_range = NO;
56+
57+
58+
# Test if accessing global optimizer_force_index_for_range gives error
59+
60+
SET @@global.optimizer_force_index_for_range = 1;
61+
SELECT @@global.optimizer_force_index_for_range;
62+
SET @@global.optimizer_force_index_for_range = 0;
63+
64+
65+
# Check if the value in GLOBAL Table contains variable value
66+
67+
SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_force_index_for_range';
68+
69+
70+
# Check if the value in GLOBAL Table matches value in variable
71+
72+
SELECT IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE
73+
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
74+
WHERE VARIABLE_NAME='optimizer_force_index_for_range';
75+
SELECT @@session.optimizer_force_index_for_range;
76+
SELECT VARIABLE_VALUE
77+
FROM INFORMATION_SCHEMA.SESSION_VARIABLES
78+
WHERE VARIABLE_NAME='optimizer_force_index_for_range';
79+
80+
81+
# Check if ON and OFF values can be used on variable
82+
83+
SET @@session.optimizer_force_index_for_range = OFF;
84+
SELECT @@session.optimizer_force_index_for_range;
85+
SET @@session.optimizer_force_index_for_range = ON;
86+
SELECT @@session.optimizer_force_index_for_range;
87+
88+
89+
# Check if TRUE and FALSE values can be used on variable
90+
91+
SET @@session.optimizer_force_index_for_range = TRUE;
92+
SELECT @@session.optimizer_force_index_for_range;
93+
SET @@session.optimizer_force_index_for_range = FALSE;
94+
SELECT @@session.optimizer_force_index_for_range;
95+
96+
97+
# Restore initial value
98+
99+
SET @@session.optimizer_force_index_for_range = @session_start_value;
100+
SELECT @@session.optimizer_force_index_for_range;
101+
SET @@global.optimizer_force_index_for_range = @global_start_value;
102+
SELECT @@global.optimizer_force_index_for_range;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,55 @@
1+
set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range;
2+
3+
create table t (i int, j int, primary key (i, j));
4+
insert into t values (1, 1);
5+
insert into t values (1, 2);
6+
insert into t values (2, 1);
7+
insert into t values (2, 2);
8+
insert into t values (3, 1);
9+
insert into t values (3, 2);
10+
11+
--echo # Test range plans
12+
set optimizer_force_index_for_range = on;
13+
--replace_column 9 #
14+
explain select i from t where i in (1, 2, 3) and j in (1, 2);
15+
--replace_column 9 #
16+
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2);
17+
set optimizer_force_index_for_range = off;
18+
--replace_column 9 #
19+
explain select i from t where i in (1, 2, 3) and j in (1, 2);
20+
--replace_column 9 #
21+
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2);
22+
23+
--echo # Test group-by plans.
24+
set optimizer_force_index_for_range = on;
25+
--replace_column 9 #
26+
explain select distinct i from t;
27+
--replace_column 9 #
28+
explain select distinct i from t force index (primary);
29+
set optimizer_force_index_for_range = off;
30+
--replace_column 9 #
31+
explain select distinct i from t;
32+
--replace_column 9 #
33+
explain select distinct i from t force index (primary);
34+
35+
--echo # Test skip-scan plans.
36+
set optimizer_switch = 'skip_scan=on';
37+
set optimizer_force_index_for_range = on;
38+
--replace_column 9 #
39+
explain select i from t where j > 1;
40+
--replace_column 9 #
41+
explain select i from t force index (primary) where j > 1;
42+
set optimizer_force_index_for_range = off;
43+
--replace_column 9 #
44+
explain select i from t where j > 1;
45+
--replace_column 9 #
46+
explain select i from t force index (primary) where j > 1;
47+
set optimizer_switch = 'skip_scan=off';
48+
49+
--echo # Test that in absence of range plan, index is used.
50+
set optimizer_force_index_for_range = on;
51+
--replace_column 9 #
52+
explain select i from t force index (primary) where j > 1;
53+
54+
drop table t;
55+
set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range;

sql/opt_range.cc

+6-1
Original file line numberDiff line numberDiff line change
@@ -2902,7 +2902,12 @@ int SQL_SELECT::test_quick_select(THD *thd, key_map keys_to_use,
29022902
param.key_parts_end=key_parts;
29032903

29042904
/* Calculate cost of full index read for the shortest covering index */
2905-
if (!head->covering_keys.is_clear_all())
2905+
if (!head->covering_keys.is_clear_all() &&
2906+
/*
2907+
If optimizer_force_index_for_range is on and force index is used,
2908+
then skip calculating index scan cost.
2909+
*/
2910+
!(thd->variables.optimizer_force_index_for_range && head->force_index))
29062911
{
29072912
int key_for_use= find_shortest_key(head, &head->covering_keys);
29082913
double key_read_time=

sql/sql_class.h

+1
Original file line numberDiff line numberDiff line change
@@ -638,6 +638,7 @@ typedef struct system_variables
638638
long optimizer_trace_limit;
639639
ulong optimizer_trace_max_mem_size;
640640
my_bool optimizer_low_limit_heuristic;
641+
my_bool optimizer_force_index_for_range;
641642
sql_mode_t sql_mode; ///< which non-standard SQL behaviour should be enabled
642643
ulonglong option_bits; ///< OPTION_xxx constants, e.g. OPTION_PROFILING
643644
ha_rows select_limit;

sql/sys_vars.cc

+6
Original file line numberDiff line numberDiff line change
@@ -2602,6 +2602,12 @@ static Sys_var_mybool Sys_optimizer_low_limit_heuristic(
26022602
SESSION_VAR(optimizer_low_limit_heuristic),
26032603
CMD_LINE(OPT_ARG), DEFAULT(TRUE));
26042604

2605+
static Sys_var_mybool Sys_optimizer_force_index_for_range(
2606+
"optimizer_force_index_for_range",
2607+
"If enabled, FORCE INDEX will also try to force a range plan.",
2608+
SESSION_VAR(optimizer_force_index_for_range),
2609+
CMD_LINE(OPT_ARG), DEFAULT(FALSE));
2610+
26052611
static const char *optimizer_switch_names[]=
26062612
{
26072613
"index_merge", "index_merge_union", "index_merge_sort_union",

0 commit comments

Comments
 (0)