-
Notifications
You must be signed in to change notification settings - Fork 713
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
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
- Loading branch information
1 parent
bcb7d9c
commit b01ff6a
Showing
9 changed files
with
333 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,62 @@ | ||
set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range; | ||
create table t (i int, j int, primary key (i, j)); | ||
insert into t values (1, 1); | ||
insert into t values (1, 2); | ||
insert into t values (2, 1); | ||
insert into t values (2, 2); | ||
insert into t values (3, 1); | ||
insert into t values (3, 2); | ||
# Test range plans | ||
set optimizer_force_index_for_range = on; | ||
explain select i from t where i in (1, 2, 3) and j in (1, 2); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t range PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
set optimizer_force_index_for_range = off; | ||
explain select i from t where i in (1, 2, 3) and j in (1, 2); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
# Test group-by plans. | ||
set optimizer_force_index_for_range = on; | ||
explain select distinct i from t; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index | ||
explain select distinct i from t force index (primary); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t range PRIMARY PRIMARY 4 NULL # Using index for group-by | ||
set optimizer_force_index_for_range = off; | ||
explain select distinct i from t; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index | ||
explain select distinct i from t force index (primary); | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using index | ||
# Test skip-scan plans. | ||
set optimizer_switch = 'skip_scan=on'; | ||
set optimizer_force_index_for_range = on; | ||
explain select i from t where j > 1; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
explain select i from t force index (primary) where j > 1; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t range PRIMARY PRIMARY 8 NULL # Using where; Using index for skip scan | ||
set optimizer_force_index_for_range = off; | ||
explain select i from t where j > 1; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
explain select i from t force index (primary) where j > 1; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index PRIMARY PRIMARY 8 NULL # Using where; Using index | ||
set optimizer_switch = 'skip_scan=off'; | ||
# Test that in absence of range plan, index is used. | ||
set optimizer_force_index_for_range = on; | ||
explain select i from t force index (primary) where j > 1; | ||
id select_type table type possible_keys key key_len ref rows Extra | ||
1 SIMPLE t index NULL PRIMARY 8 NULL # Using where; Using index | ||
drop table t; | ||
set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range; |
93 changes: 93 additions & 0 deletions
93
mysql-test/suite/sys_vars/r/optimizer_force_index_for_range_basic.result
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,93 @@ | ||
SET @session_start_value = @@session.optimizer_force_index_for_range; | ||
SELECT @session_start_value; | ||
@session_start_value | ||
0 | ||
SET @global_start_value = @@global.optimizer_force_index_for_range; | ||
SELECT @global_start_value; | ||
@global_start_value | ||
0 | ||
SET @@session.optimizer_force_index_for_range = 0; | ||
SET @@session.optimizer_force_index_for_range = DEFAULT; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@session.optimizer_force_index_for_range = 1; | ||
SET @@session.optimizer_force_index_for_range = DEFAULT; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET optimizer_force_index_for_range = 1; | ||
SELECT @@optimizer_force_index_for_range; | ||
@@optimizer_force_index_for_range | ||
1 | ||
SELECT session.optimizer_force_index_for_range; | ||
ERROR 42S02: Unknown table 'session' in field list | ||
SELECT local.optimizer_force_index_for_range; | ||
ERROR 42S02: Unknown table 'local' in field list | ||
SET session optimizer_force_index_for_range = 0; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@session.optimizer_force_index_for_range = 0; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@session.optimizer_force_index_for_range = 1; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
1 | ||
SET @@session.optimizer_force_index_for_range = -1; | ||
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of '-1' | ||
SET @@session.optimizer_force_index_for_range = 2; | ||
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of '2' | ||
SET @@session.optimizer_force_index_for_range = "T"; | ||
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'T' | ||
SET @@session.optimizer_force_index_for_range = "Y"; | ||
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'Y' | ||
SET @@session.optimizer_force_index_for_range = NO; | ||
ERROR 42000: Variable 'optimizer_force_index_for_range' can't be set to the value of 'NO' | ||
SET @@global.optimizer_force_index_for_range = 1; | ||
SELECT @@global.optimizer_force_index_for_range; | ||
@@global.optimizer_force_index_for_range | ||
1 | ||
SET @@global.optimizer_force_index_for_range = 0; | ||
SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
count(VARIABLE_VALUE) | ||
1 | ||
SELECT IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE | ||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES | ||
WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE | ||
1 | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
1 | ||
SELECT VARIABLE_VALUE | ||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES | ||
WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
VARIABLE_VALUE | ||
ON | ||
SET @@session.optimizer_force_index_for_range = OFF; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@session.optimizer_force_index_for_range = ON; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
1 | ||
SET @@session.optimizer_force_index_for_range = TRUE; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
1 | ||
SET @@session.optimizer_force_index_for_range = FALSE; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@session.optimizer_force_index_for_range = @session_start_value; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
@@session.optimizer_force_index_for_range | ||
0 | ||
SET @@global.optimizer_force_index_for_range = @global_start_value; | ||
SELECT @@global.optimizer_force_index_for_range; | ||
@@global.optimizer_force_index_for_range | ||
0 |
102 changes: 102 additions & 0 deletions
102
mysql-test/suite/sys_vars/t/optimizer_force_index_for_range_basic.test
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,102 @@ | ||
--source include/load_sysvars.inc | ||
|
||
|
||
# Saving initial value of optimizer_force_index_for_range in a temporary variable | ||
|
||
SET @session_start_value = @@session.optimizer_force_index_for_range; | ||
SELECT @session_start_value; | ||
SET @global_start_value = @@global.optimizer_force_index_for_range; | ||
SELECT @global_start_value; | ||
|
||
# Display the DEFAULT value of optimizer_force_index_for_range | ||
|
||
SET @@session.optimizer_force_index_for_range = 0; | ||
SET @@session.optimizer_force_index_for_range = DEFAULT; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
SET @@session.optimizer_force_index_for_range = 1; | ||
SET @@session.optimizer_force_index_for_range = DEFAULT; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
|
||
# Check if optimizer_force_index_for_range can be accessed with and without @@ sign | ||
|
||
SET optimizer_force_index_for_range = 1; | ||
SELECT @@optimizer_force_index_for_range; | ||
|
||
--Error ER_UNKNOWN_TABLE | ||
SELECT session.optimizer_force_index_for_range; | ||
|
||
--Error ER_UNKNOWN_TABLE | ||
SELECT local.optimizer_force_index_for_range; | ||
|
||
SET session optimizer_force_index_for_range = 0; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
# change the value of optimizer_force_index_for_range to a valid value | ||
|
||
SET @@session.optimizer_force_index_for_range = 0; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
SET @@session.optimizer_force_index_for_range = 1; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
|
||
# Change the value of optimizer_force_index_for_range to invalid value | ||
|
||
--Error ER_WRONG_VALUE_FOR_VAR | ||
SET @@session.optimizer_force_index_for_range = -1; | ||
--Error ER_WRONG_VALUE_FOR_VAR | ||
SET @@session.optimizer_force_index_for_range = 2; | ||
--Error ER_WRONG_VALUE_FOR_VAR | ||
SET @@session.optimizer_force_index_for_range = "T"; | ||
--Error ER_WRONG_VALUE_FOR_VAR | ||
SET @@session.optimizer_force_index_for_range = "Y"; | ||
--Error ER_WRONG_VALUE_FOR_VAR | ||
SET @@session.optimizer_force_index_for_range = NO; | ||
|
||
|
||
# Test if accessing global optimizer_force_index_for_range gives error | ||
|
||
SET @@global.optimizer_force_index_for_range = 1; | ||
SELECT @@global.optimizer_force_index_for_range; | ||
SET @@global.optimizer_force_index_for_range = 0; | ||
|
||
|
||
# Check if the value in GLOBAL Table contains variable value | ||
|
||
SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
|
||
|
||
# Check if the value in GLOBAL Table matches value in variable | ||
|
||
SELECT IF(@@session.optimizer_force_index_for_range, "ON", "OFF") = VARIABLE_VALUE | ||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES | ||
WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
SELECT VARIABLE_VALUE | ||
FROM INFORMATION_SCHEMA.SESSION_VARIABLES | ||
WHERE VARIABLE_NAME='optimizer_force_index_for_range'; | ||
|
||
|
||
# Check if ON and OFF values can be used on variable | ||
|
||
SET @@session.optimizer_force_index_for_range = OFF; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
SET @@session.optimizer_force_index_for_range = ON; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
|
||
# Check if TRUE and FALSE values can be used on variable | ||
|
||
SET @@session.optimizer_force_index_for_range = TRUE; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
SET @@session.optimizer_force_index_for_range = FALSE; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
|
||
|
||
# Restore initial value | ||
|
||
SET @@session.optimizer_force_index_for_range = @session_start_value; | ||
SELECT @@session.optimizer_force_index_for_range; | ||
SET @@global.optimizer_force_index_for_range = @global_start_value; | ||
SELECT @@global.optimizer_force_index_for_range; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,55 @@ | ||
set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range; | ||
|
||
create table t (i int, j int, primary key (i, j)); | ||
insert into t values (1, 1); | ||
insert into t values (1, 2); | ||
insert into t values (2, 1); | ||
insert into t values (2, 2); | ||
insert into t values (3, 1); | ||
insert into t values (3, 2); | ||
|
||
--echo # Test range plans | ||
set optimizer_force_index_for_range = on; | ||
--replace_column 9 # | ||
explain select i from t where i in (1, 2, 3) and j in (1, 2); | ||
--replace_column 9 # | ||
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); | ||
set optimizer_force_index_for_range = off; | ||
--replace_column 9 # | ||
explain select i from t where i in (1, 2, 3) and j in (1, 2); | ||
--replace_column 9 # | ||
explain select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); | ||
|
||
--echo # Test group-by plans. | ||
set optimizer_force_index_for_range = on; | ||
--replace_column 9 # | ||
explain select distinct i from t; | ||
--replace_column 9 # | ||
explain select distinct i from t force index (primary); | ||
set optimizer_force_index_for_range = off; | ||
--replace_column 9 # | ||
explain select distinct i from t; | ||
--replace_column 9 # | ||
explain select distinct i from t force index (primary); | ||
|
||
--echo # Test skip-scan plans. | ||
set optimizer_switch = 'skip_scan=on'; | ||
set optimizer_force_index_for_range = on; | ||
--replace_column 9 # | ||
explain select i from t where j > 1; | ||
--replace_column 9 # | ||
explain select i from t force index (primary) where j > 1; | ||
set optimizer_force_index_for_range = off; | ||
--replace_column 9 # | ||
explain select i from t where j > 1; | ||
--replace_column 9 # | ||
explain select i from t force index (primary) where j > 1; | ||
set optimizer_switch = 'skip_scan=off'; | ||
|
||
--echo # Test that in absence of range plan, index is used. | ||
set optimizer_force_index_for_range = on; | ||
--replace_column 9 # | ||
explain select i from t force index (primary) where j > 1; | ||
|
||
drop table t; | ||
set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters