From 6f0ef5f2ee73ce73c530056df32bee4c3c1cfc99 Mon Sep 17 00:00:00 2001 From: Manuel Ung Date: Fri, 8 Mar 2019 10:44:25 -0800 Subject: [PATCH] FB8-167: Add variable to force range plans if force index is used (#967) (#967) Summary: Jira ticket: https://jira.percona.com/browse/FB8-167 Reference Patch: https://github.com/facebook/mysql-5.6/commit/b01ff6a 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. Pull Request resolved: https://github.com/facebook/mysql-5.6/pull/967 Reviewed By: lloyd Differential Revision: D14387089 Pulled By: lth --- mysql-test/collections/disabled_rocksdb.def | 2 - mysql-test/r/mysqld--help-notwin.result | 4 + mysql-test/r/opt_hints_set_var.result | 17 +++ .../r/optimizer_force_index_for_range.result | 86 +++++++++++++++ ...timizer_force_index_for_range_basic.result | 93 ++++++++++++++++ ...optimizer_force_index_for_range_basic.test | 102 ++++++++++++++++++ mysql-test/t/opt_hints_set_var.test | 7 ++ .../t/optimizer_force_index_for_range.test | 52 +++++++++ sql/range_optimizer/range_optimizer.cc | 7 +- sql/sys_vars.cc | 6 ++ sql/system_variables.h | 1 + 11 files changed, 374 insertions(+), 3 deletions(-) create mode 100644 mysql-test/r/optimizer_force_index_for_range.result create mode 100644 mysql-test/suite/sys_vars/r/optimizer_force_index_for_range_basic.result create mode 100644 mysql-test/suite/sys_vars/t/optimizer_force_index_for_range_basic.test create mode 100644 mysql-test/t/optimizer_force_index_for_range.test diff --git a/mysql-test/collections/disabled_rocksdb.def b/mysql-test/collections/disabled_rocksdb.def index bbd4f221a132..54c6e75d1e2e 100644 --- a/mysql-test/collections/disabled_rocksdb.def +++ b/mysql-test/collections/disabled_rocksdb.def @@ -74,8 +74,6 @@ rocksdb.bypass_select_range_sk_bloom : BUG#0000 Rebase: not-yet-implemented rocksdb.bypass_select_basic_bloom : BUG#0000 Rebase: not-yet-implemented rocksdb.rocksdb_deadlock_detect_rc : BUG#0000 Rebase: not-yet-implemented rocksdb.rocksdb_deadlock_detect_rr : BUG#0000 Rebase: not-yet-implemented -rocksdb.bloomfilter2 : BUG#0000 Rebase: not-yet-implemented -rocksdb.bloomfilter3 : BUG#0000 Rebase: not-yet-implemented rocksdb.track_and_verify_wals_in_manifest : BUG#0000 Rebase: not-yet-implemented rocksdb.mysqldump : BUG#0000 Rebase: not-yet-implemented rocksdb_rpl.rocksdb_slave_check_before_image_consistency : BUG#0000 Rebase: not-yet-implemented diff --git a/mysql-test/r/mysqld--help-notwin.result b/mysql-test/r/mysqld--help-notwin.result index 274f4216e20f..01219a10dc55 100644 --- a/mysql-test/r/mysqld--help-notwin.result +++ b/mysql-test/r/mysqld--help-notwin.result @@ -867,6 +867,9 @@ The following options may be given as the first argument: value is 0 then mysqld will reserve max_connections*5 or max_connections + table_open_cache*2 (whichever is larger) number of file descriptors + --optimizer-force-index-for-range + If enabled, FORCE INDEX will also try to force a range + plan. --optimizer-max-subgraph-pairs=# Maximum depth of subgraph pairs a query can have before the hypergraph join optimizer starts reducing the search @@ -2592,6 +2595,7 @@ offline-mode FALSE old FALSE old-alter-table FALSE old-style-user-limits FALSE +optimizer-force-index-for-range FALSE optimizer-max-subgraph-pairs 100000 optimizer-prune-level 1 optimizer-search-depth 62 diff --git a/mysql-test/r/opt_hints_set_var.result b/mysql-test/r/opt_hints_set_var.result index 648f0917b5cb..e9b0d309dfc7 100644 --- a/mysql-test/r/opt_hints_set_var.result +++ b/mysql-test/r/opt_hints_set_var.result @@ -461,6 +461,23 @@ VARIABLE_VALUE 0 VARIABLE_VALUE 1 +EXPLAIN SELECT DISTINCT a FROM t1 FORCE INDEX (PRIMARY); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 NULL index PRIMARY PRIMARY 4 NULL 4 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select distinct `test`.`t1`.`a` AS `a` from `test`.`t1` FORCE INDEX (PRIMARY) +EXPLAIN SELECT /*+ SET_VAR(optimizer_force_index_for_range=1) */ DISTINCT a FROM t1 FORCE INDEX (PRIMARY); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 NULL range PRIMARY PRIMARY 4 NULL 5 100.00 Using index for group-by +Warnings: +Note 1003 /* select#1 */ select /*+ SET_VAR(optimizer_force_index_for_range=1) */ distinct `test`.`t1`.`a` AS `a` from `test`.`t1` FORCE INDEX (PRIMARY) +CALL test_hint("SET_VAR(optimizer_force_index_for_range=1)", "optimizer_force_index_for_range"); +VARIABLE_VALUE +OFF +VARIABLE_VALUE +ON +VARIABLE_VALUE +OFF DROP TABLE t1, t2, t3; CREATE TABLE t1 ( diff --git a/mysql-test/r/optimizer_force_index_for_range.result b/mysql-test/r/optimizer_force_index_for_range.result new file mode 100644 index 000000000000..8ce301d44786 --- /dev/null +++ b/mysql-test/r/optimizer_force_index_for_range.result @@ -0,0 +1,86 @@ +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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` where ((`test`.`t`.`i` in (1,2,3)) and (`test`.`t`.`j` in (1,2))) +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE i IN (1, 2, 3) AND j IN (1, 2); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL range PRIMARY PRIMARY 8 NULL # 100.00 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) where ((`test`.`t`.`i` in (1,2,3)) and (`test`.`t`.`j` in (1,2))) +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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` where ((`test`.`t`.`i` in (1,2,3)) and (`test`.`t`.`j` in (1,2))) +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE i IN (1, 2, 3) AND j IN (1, 2); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) where ((`test`.`t`.`i` in (1,2,3)) and (`test`.`t`.`j` in (1,2))) +# Test group-by plans. +SET optimizer_force_index_for_range = ON; +EXPLAIN SELECT DISTINCT i FROM t; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select distinct `test`.`t`.`i` AS `i` from `test`.`t` +EXPLAIN SELECT DISTINCT i FROM t FORCE INDEX (PRIMARY); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL range PRIMARY PRIMARY 4 NULL # 100.00 Using index for group-by +Warnings: +Note 1003 /* select#1 */ select distinct `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) +SET optimizer_force_index_for_range = OFF; +EXPLAIN SELECT DISTINCT i FROM t; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select distinct `test`.`t`.`i` AS `i` from `test`.`t` +EXPLAIN SELECT DISTINCT i FROM t FORCE INDEX (PRIMARY); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select distinct `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) +# 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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 33.33 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` where (`test`.`t`.`j` > 1) +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE j > 1; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL range PRIMARY PRIMARY 8 NULL # 100.00 Using where; Using index for skip scan +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) where (`test`.`t`.`j` > 1) +SET optimizer_force_index_for_range = OFF; +EXPLAIN SELECT i FROM t WHERE j > 1; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 33.33 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` where (`test`.`t`.`j` > 1) +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE j > 1; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index PRIMARY PRIMARY 8 NULL # 33.33 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) where (`test`.`t`.`j` > 1) +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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index NULL PRIMARY 8 NULL # 33.33 Using where; Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (PRIMARY) where (`test`.`t`.`j` > 1) +DROP TABLE t; diff --git a/mysql-test/suite/sys_vars/r/optimizer_force_index_for_range_basic.result b/mysql-test/suite/sys_vars/r/optimizer_force_index_for_range_basic.result new file mode 100644 index 000000000000..bc4cdee95b56 --- /dev/null +++ b/mysql-test/suite/sys_vars/r/optimizer_force_index_for_range_basic.result @@ -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 performance_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 performance_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 performance_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 diff --git a/mysql-test/suite/sys_vars/t/optimizer_force_index_for_range_basic.test b/mysql-test/suite/sys_vars/t/optimizer_force_index_for_range_basic.test new file mode 100644 index 000000000000..a1d30efe7b79 --- /dev/null +++ b/mysql-test/suite/sys_vars/t/optimizer_force_index_for_range_basic.test @@ -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 performance_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 performance_schema.session_variables +WHERE VARIABLE_NAME='optimizer_force_index_for_range'; +SELECT @@session.optimizer_force_index_for_range; +SELECT VARIABLE_VALUE +FROM performance_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; diff --git a/mysql-test/t/opt_hints_set_var.test b/mysql-test/t/opt_hints_set_var.test index fd497334de46..aed075e26a0f 100644 --- a/mysql-test/t/opt_hints_set_var.test +++ b/mysql-test/t/opt_hints_set_var.test @@ -259,6 +259,13 @@ t2.a IN (SELECT t3.b FROM t3 JOIN t1 t4 ON t3.b = t4.b); CALL test_hint("SET_VAR(optimizer_search_depth=1)", "optimizer_search_depth"); CALL test_hint("SET_VAR(optimizer_prune_level=0)", "optimizer_prune_level"); +# Testing optimizer_force_index_for_range variable +EXPLAIN SELECT DISTINCT a FROM t1 FORCE INDEX (PRIMARY); + +EXPLAIN SELECT /*+ SET_VAR(optimizer_force_index_for_range=1) */ DISTINCT a FROM t1 FORCE INDEX (PRIMARY); + +CALL test_hint("SET_VAR(optimizer_force_index_for_range=1)", "optimizer_force_index_for_range"); + DROP TABLE t1, t2, t3; diff --git a/mysql-test/t/optimizer_force_index_for_range.test b/mysql-test/t/optimizer_force_index_for_range.test new file mode 100644 index 000000000000..f8a9fc483f75 --- /dev/null +++ b/mysql-test/t/optimizer_force_index_for_range.test @@ -0,0 +1,52 @@ +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 10 # +EXPLAIN SELECT i FROM t WHERE i IN (1, 2, 3) AND j IN (1, 2); +--replace_column 10 # +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 10 # +EXPLAIN SELECT i FROM t WHERE i IN (1, 2, 3) AND j IN (1, 2); +--replace_column 10 # +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 10 # +EXPLAIN SELECT DISTINCT i FROM t; +--replace_column 10 # +EXPLAIN SELECT DISTINCT i FROM t FORCE INDEX (PRIMARY); +SET optimizer_force_index_for_range = OFF; +--replace_column 10 # +EXPLAIN SELECT DISTINCT i FROM t; +--replace_column 10 # +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 10 # +EXPLAIN SELECT i FROM t WHERE j > 1; +--replace_column 10 # +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE j > 1; +SET optimizer_force_index_for_range = OFF; +--replace_column 10 # +EXPLAIN SELECT i FROM t WHERE j > 1; +--replace_column 10 # +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 10 # +EXPLAIN SELECT i FROM t FORCE INDEX (PRIMARY) WHERE j > 1; + +DROP TABLE t; diff --git a/sql/range_optimizer/range_optimizer.cc b/sql/range_optimizer/range_optimizer.cc index 0d26b16517e5..ec7e95918858 100644 --- a/sql/range_optimizer/range_optimizer.cc +++ b/sql/range_optimizer/range_optimizer.cc @@ -612,7 +612,12 @@ int test_quick_select(THD *thd, MEM_ROOT *return_mem_root, thd->optimizer_switch_flag(OPTIMIZER_SWITCH_INDEX_MERGE_INTERSECT); /* Calculate cost of full index read for the shortest covering index */ - if (!table->covering_keys.is_clear_all()) { + if (!table->covering_keys.is_clear_all() && + /* + If optimizer_force_index_for_range is on and force index is used, + then skip calculating index scan cost. + */ + !(thd->variables.optimizer_force_index_for_range && table->force_index)) { int key_for_use = find_shortest_key(table, &table->covering_keys); // find_shortest_key() should return a valid key: assert(key_for_use != MAX_KEY); diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 39a439a38d02..a5b06f3130ae 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -3396,6 +3396,12 @@ static Sys_var_ulong Sys_open_files_limit( /* open_files_limit is used as a sizing hint by the performance schema. */ sys_var::PARSE_EARLY); +static Sys_var_bool Sys_optimizer_force_index_for_range( + "optimizer_force_index_for_range", + "If enabled, FORCE INDEX will also try to force a range plan.", + HINT_UPDATEABLE SESSION_VAR(optimizer_force_index_for_range), + CMD_LINE(OPT_ARG), DEFAULT(false)); + /// @todo change to enum static Sys_var_ulong Sys_optimizer_prune_level( "optimizer_prune_level", diff --git a/sql/system_variables.h b/sql/system_variables.h index d3a1d1bf2d23..f213d75a0fcc 100644 --- a/sql/system_variables.h +++ b/sql/system_variables.h @@ -244,6 +244,7 @@ struct System_variables { long optimizer_trace_offset; long optimizer_trace_limit; ulong optimizer_trace_max_mem_size; + bool optimizer_force_index_for_range; sql_mode_t sql_mode; ///< which non-standard SQL behaviour should be enabled ulonglong option_bits; ///< OPTION_xxx constants, e.g. OPTION_PROFILING ha_rows select_limit;