From b90e801ed87bd2610a190af7cfa2f64b22d9394e Mon Sep 17 00:00:00 2001 From: Manuel Ung Date: Wed, 18 Apr 2018 14:00:56 -0700 Subject: [PATCH] Add variable to disable full table/index scans Summary: There are cases where it is always unacceptable for a client to be doing full table scans. To prevent this from happening, add a new variable optimizer_full_scan. When it is turned off, it will return a new error code ER_FULL_SCAN_DISABLED. For best results, use with optimizer_force_index_for_range. Currently, it does not fallback to alternative plans because we check at the end of query planning. Reviewed By: hermanlee Differential Revision: D7528820 fbshipit-source-id: 94fcd07 --- .../r/mysqld--help-notwin-profiling.result | 4 + mysql-test/r/mysqld--help-notwin.result | 4 + mysql-test/r/optimizer_full_scan.result | 99 +++++++++++++++++ .../r/optimizer_full_scan_basic.result | 93 ++++++++++++++++ .../sys_vars/t/optimizer_full_scan_basic.test | 102 ++++++++++++++++++ mysql-test/t/optimizer_full_scan.test | 65 +++++++++++ sql/share/errmsg-utf8.txt | 3 + sql/sql_class.h | 1 + sql/sql_select.cc | 12 +++ sql/sys_vars.cc | 6 ++ 10 files changed, 389 insertions(+) create mode 100644 mysql-test/r/optimizer_full_scan.result create mode 100644 mysql-test/suite/sys_vars/r/optimizer_full_scan_basic.result create mode 100644 mysql-test/suite/sys_vars/t/optimizer_full_scan_basic.test create mode 100644 mysql-test/t/optimizer_full_scan.test diff --git a/mysql-test/r/mysqld--help-notwin-profiling.result b/mysql-test/r/mysqld--help-notwin-profiling.result index d1ea9afa3446..818b071547a6 100644 --- a/mysql-test/r/mysqld--help-notwin-profiling.result +++ b/mysql-test/r/mysqld--help-notwin-profiling.result @@ -722,6 +722,9 @@ The following options may be given as the first argument: --optimizer-force-index-for-range If enabled, FORCE INDEX will also try to force a range plan. + --optimizer-full-scan + Enable full table and index scans. + (Defaults to on; use --skip-optimizer-full-scan to disable.) --optimizer-low-limit-heuristic Enable low limit heuristic. (Defaults to on; use --skip-optimizer-low-limit-heuristic to disable.) @@ -2037,6 +2040,7 @@ old-alter-table FALSE old-passwords 0 old-style-user-limits FALSE optimizer-force-index-for-range FALSE +optimizer-full-scan TRUE optimizer-low-limit-heuristic TRUE optimizer-prune-level 1 optimizer-search-depth 62 diff --git a/mysql-test/r/mysqld--help-notwin.result b/mysql-test/r/mysqld--help-notwin.result index c586696c2ef7..0624bc971fbe 100644 --- a/mysql-test/r/mysqld--help-notwin.result +++ b/mysql-test/r/mysqld--help-notwin.result @@ -722,6 +722,9 @@ The following options may be given as the first argument: --optimizer-force-index-for-range If enabled, FORCE INDEX will also try to force a range plan. + --optimizer-full-scan + Enable full table and index scans. + (Defaults to on; use --skip-optimizer-full-scan to disable.) --optimizer-low-limit-heuristic Enable low limit heuristic. (Defaults to on; use --skip-optimizer-low-limit-heuristic to disable.) @@ -2035,6 +2038,7 @@ old-alter-table FALSE old-passwords 0 old-style-user-limits FALSE optimizer-force-index-for-range FALSE +optimizer-full-scan TRUE optimizer-low-limit-heuristic TRUE optimizer-prune-level 1 optimizer-search-depth 62 diff --git a/mysql-test/r/optimizer_full_scan.result b/mysql-test/r/optimizer_full_scan.result new file mode 100644 index 000000000000..0f139aab0562 --- /dev/null +++ b/mysql-test/r/optimizer_full_scan.result @@ -0,0 +1,99 @@ +set @orig_optimizer_full_scan = @@optimizer_full_scan; +set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range; +create table t (i int, j int, key(i)); +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); +analyze table t; +Table Op Msg_type Msg_text +test.t analyze status OK +# Basic tests +explain select * from t; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t ALL NULL NULL NULL NULL # NULL +set optimizer_full_scan = off; +select * from t; +ERROR HY000: Full table/index scan is disabled +set optimizer_full_scan = on; +select * from t; +i j +1 1 +1 2 +2 1 +2 2 +3 1 +3 2 +explain select * from t force index (i); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t ALL NULL NULL NULL NULL # NULL +set optimizer_full_scan = off; +select i from t force index (i); +ERROR HY000: Full table/index scan is disabled +set optimizer_full_scan = on; +select i from t force index (i); +i +1 +1 +2 +2 +3 +3 +explain select * from t a, t b where a.i = b.i; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE a ALL i NULL NULL NULL # NULL +1 SIMPLE b ALL i NULL NULL NULL # Using where; Using join buffer (Block Nested Loop) +set optimizer_full_scan = off; +select * from t a, t b where a.i = b.i; +ERROR HY000: Full table/index scan is disabled +set optimizer_full_scan = on; +select * from t a, t b where a.i = b.i; +i j i j +1 1 1 1 +1 2 1 1 +1 1 1 2 +1 2 1 2 +2 1 2 1 +2 2 2 1 +2 1 2 2 +2 2 2 2 +3 1 3 1 +3 2 3 1 +3 1 3 2 +3 2 3 2 +explain select * from t a straight_join t b where a.i = 10; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE a ref i i 5 const # NULL +1 SIMPLE b ALL NULL NULL NULL NULL # Using join buffer (Block Nested Loop) +set optimizer_full_scan = off; +select * from t a straight_join t b where a.i = 10; +ERROR HY000: Full table/index scan is disabled +set optimizer_full_scan = on; +select * from t a straight_join t b where a.i = 10; +i j i j +# Test integration with optimizer_force_index_for_range +alter table t drop index i, add primary key (i, j); +# Test range plans +set optimizer_force_index_for_range = on; +set optimizer_full_scan = 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 +select i from t where i in (1, 2, 3) and j in (1, 2); +ERROR HY000: Full table/index scan is disabled +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 +select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); +i +1 +1 +2 +2 +3 +3 +drop table t; +set optimizer_full_scan = @orig_optimizer_full_scan; +set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range; diff --git a/mysql-test/suite/sys_vars/r/optimizer_full_scan_basic.result b/mysql-test/suite/sys_vars/r/optimizer_full_scan_basic.result new file mode 100644 index 000000000000..2ebd0159e029 --- /dev/null +++ b/mysql-test/suite/sys_vars/r/optimizer_full_scan_basic.result @@ -0,0 +1,93 @@ +SET @session_start_value = @@session.optimizer_full_scan; +SELECT @session_start_value; +@session_start_value +1 +SET @global_start_value = @@global.optimizer_full_scan; +SELECT @global_start_value; +@global_start_value +1 +SET @@session.optimizer_full_scan = 0; +SET @@session.optimizer_full_scan = DEFAULT; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET @@session.optimizer_full_scan = 1; +SET @@session.optimizer_full_scan = DEFAULT; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET optimizer_full_scan = 1; +SELECT @@optimizer_full_scan; +@@optimizer_full_scan +1 +SELECT session.optimizer_full_scan; +ERROR 42S02: Unknown table 'session' in field list +SELECT local.optimizer_full_scan; +ERROR 42S02: Unknown table 'local' in field list +SET session optimizer_full_scan = 0; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +0 +SET @@session.optimizer_full_scan = 0; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +0 +SET @@session.optimizer_full_scan = 1; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET @@session.optimizer_full_scan = -1; +ERROR 42000: Variable 'optimizer_full_scan' can't be set to the value of '-1' +SET @@session.optimizer_full_scan = 2; +ERROR 42000: Variable 'optimizer_full_scan' can't be set to the value of '2' +SET @@session.optimizer_full_scan = "T"; +ERROR 42000: Variable 'optimizer_full_scan' can't be set to the value of 'T' +SET @@session.optimizer_full_scan = "Y"; +ERROR 42000: Variable 'optimizer_full_scan' can't be set to the value of 'Y' +SET @@session.optimizer_full_scan = NO; +ERROR 42000: Variable 'optimizer_full_scan' can't be set to the value of 'NO' +SET @@global.optimizer_full_scan = 1; +SELECT @@global.optimizer_full_scan; +@@global.optimizer_full_scan +1 +SET @@global.optimizer_full_scan = 0; +SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_full_scan'; +count(VARIABLE_VALUE) +1 +SELECT IF(@@session.optimizer_full_scan, "ON", "OFF") = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_full_scan'; +IF(@@session.optimizer_full_scan, "ON", "OFF") = VARIABLE_VALUE +1 +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SELECT VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_full_scan'; +VARIABLE_VALUE +ON +SET @@session.optimizer_full_scan = OFF; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +0 +SET @@session.optimizer_full_scan = ON; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET @@session.optimizer_full_scan = TRUE; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET @@session.optimizer_full_scan = FALSE; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +0 +SET @@session.optimizer_full_scan = @session_start_value; +SELECT @@session.optimizer_full_scan; +@@session.optimizer_full_scan +1 +SET @@global.optimizer_full_scan = @global_start_value; +SELECT @@global.optimizer_full_scan; +@@global.optimizer_full_scan +1 diff --git a/mysql-test/suite/sys_vars/t/optimizer_full_scan_basic.test b/mysql-test/suite/sys_vars/t/optimizer_full_scan_basic.test new file mode 100644 index 000000000000..05474af710f9 --- /dev/null +++ b/mysql-test/suite/sys_vars/t/optimizer_full_scan_basic.test @@ -0,0 +1,102 @@ +--source include/load_sysvars.inc + + +# Saving initial value of optimizer_full_scan in a temporary variable + +SET @session_start_value = @@session.optimizer_full_scan; +SELECT @session_start_value; +SET @global_start_value = @@global.optimizer_full_scan; +SELECT @global_start_value; + +# Display the DEFAULT value of optimizer_full_scan + +SET @@session.optimizer_full_scan = 0; +SET @@session.optimizer_full_scan = DEFAULT; +SELECT @@session.optimizer_full_scan; + +SET @@session.optimizer_full_scan = 1; +SET @@session.optimizer_full_scan = DEFAULT; +SELECT @@session.optimizer_full_scan; + + +# Check if optimizer_full_scan can be accessed with and without @@ sign + +SET optimizer_full_scan = 1; +SELECT @@optimizer_full_scan; + +--Error ER_UNKNOWN_TABLE +SELECT session.optimizer_full_scan; + +--Error ER_UNKNOWN_TABLE +SELECT local.optimizer_full_scan; + +SET session optimizer_full_scan = 0; +SELECT @@session.optimizer_full_scan; + +# change the value of optimizer_full_scan to a valid value + +SET @@session.optimizer_full_scan = 0; +SELECT @@session.optimizer_full_scan; +SET @@session.optimizer_full_scan = 1; +SELECT @@session.optimizer_full_scan; + + +# Change the value of optimizer_full_scan to invalid value + +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.optimizer_full_scan = -1; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.optimizer_full_scan = 2; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.optimizer_full_scan = "T"; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.optimizer_full_scan = "Y"; +--Error ER_WRONG_VALUE_FOR_VAR +SET @@session.optimizer_full_scan = NO; + + +# Test if accessing global optimizer_full_scan gives error + +SET @@global.optimizer_full_scan = 1; +SELECT @@global.optimizer_full_scan; +SET @@global.optimizer_full_scan = 0; + + +# Check if the value in GLOBAL Table contains variable value + +SELECT count(VARIABLE_VALUE) FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES WHERE VARIABLE_NAME='optimizer_full_scan'; + + +# Check if the value in GLOBAL Table matches value in variable + +SELECT IF(@@session.optimizer_full_scan, "ON", "OFF") = VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_full_scan'; +SELECT @@session.optimizer_full_scan; +SELECT VARIABLE_VALUE +FROM INFORMATION_SCHEMA.SESSION_VARIABLES +WHERE VARIABLE_NAME='optimizer_full_scan'; + + +# Check if ON and OFF values can be used on variable + +SET @@session.optimizer_full_scan = OFF; +SELECT @@session.optimizer_full_scan; +SET @@session.optimizer_full_scan = ON; +SELECT @@session.optimizer_full_scan; + + +# Check if TRUE and FALSE values can be used on variable + +SET @@session.optimizer_full_scan = TRUE; +SELECT @@session.optimizer_full_scan; +SET @@session.optimizer_full_scan = FALSE; +SELECT @@session.optimizer_full_scan; + + +# Restore initial value + +SET @@session.optimizer_full_scan = @session_start_value; +SELECT @@session.optimizer_full_scan; +SET @@global.optimizer_full_scan = @global_start_value; +SELECT @@global.optimizer_full_scan; diff --git a/mysql-test/t/optimizer_full_scan.test b/mysql-test/t/optimizer_full_scan.test new file mode 100644 index 000000000000..798239805ebf --- /dev/null +++ b/mysql-test/t/optimizer_full_scan.test @@ -0,0 +1,65 @@ +set @orig_optimizer_full_scan = @@optimizer_full_scan; +set @orig_optimizer_force_index_for_range = @@optimizer_force_index_for_range; + +create table t (i int, j int, key(i)); +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); + +analyze table t; + +--echo # Basic tests +--replace_column 9 # +explain select * from t; +set optimizer_full_scan = off; +--error ER_FULL_SCAN_DISABLED +select * from t; +set optimizer_full_scan = on; +select * from t; + +--replace_column 9 # +explain select * from t force index (i); +set optimizer_full_scan = off; +--error ER_FULL_SCAN_DISABLED +select i from t force index (i); +set optimizer_full_scan = on; +select i from t force index (i); + +--replace_column 9 # +explain select * from t a, t b where a.i = b.i; +set optimizer_full_scan = off; +--error ER_FULL_SCAN_DISABLED +select * from t a, t b where a.i = b.i; +set optimizer_full_scan = on; +select * from t a, t b where a.i = b.i; + +--replace_column 9 # +explain select * from t a straight_join t b where a.i = 10; +set optimizer_full_scan = off; +--error ER_FULL_SCAN_DISABLED +select * from t a straight_join t b where a.i = 10; +set optimizer_full_scan = on; +select * from t a straight_join t b where a.i = 10; + +--echo # Test integration with optimizer_force_index_for_range +alter table t drop index i, add primary key (i, j); + +--echo # Test range plans +set optimizer_force_index_for_range = on; +set optimizer_full_scan = off; +--replace_column 9 # +explain select i from t where i in (1, 2, 3) and j in (1, 2); +--error ER_FULL_SCAN_DISABLED +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); +select i from t force index (primary) where i in (1, 2, 3) and j in (1, 2); + +drop table t; + +set optimizer_full_scan = @orig_optimizer_full_scan; +set optimizer_force_index_for_range = @orig_optimizer_force_index_for_range; + diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 55d1071ff049..5cb64db0399d 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -7374,6 +7374,9 @@ ER_RPC_FAILED_TO_ATTACH ER_RPC_FAILED_TO_STORE_DETACHED_SESSION eng "Failed to store the detached session" +ER_FULL_SCAN_DISABLED + eng "Full table/index scan is disabled" + # # End of 5.6 error messages. # diff --git a/sql/sql_class.h b/sql/sql_class.h index 365028e09cb5..1017cd875963 100644 --- a/sql/sql_class.h +++ b/sql/sql_class.h @@ -639,6 +639,7 @@ typedef struct system_variables ulong optimizer_trace_max_mem_size; my_bool optimizer_low_limit_heuristic; my_bool optimizer_force_index_for_range; + my_bool optimizer_full_scan; 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; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ae8fbce45f4b..678c7a846c78 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -2901,6 +2901,12 @@ make_join_readinfo(JOIN *join, ulonglong options, uint no_jbuf_after) join->thd->set_status_no_index_used(); if (statistics) join->thd->inc_status_select_scan(); + /* Block full table/index scans, if optimizer_full_scan is off. */ + if (!join->thd->variables.optimizer_full_scan && + !(join->select_options & SELECT_DESCRIBE)) { + my_error(ER_FULL_SCAN_DISABLED, MYF(0)); + DBUG_RETURN(TRUE); + } } } else @@ -2915,6 +2921,12 @@ make_join_readinfo(JOIN *join, ulonglong options, uint no_jbuf_after) join->thd->set_status_no_index_used(); if (statistics) join->thd->inc_status_select_full_join(); + /* Block full table/index scans, if optimizer_full_scan is off. */ + if (!join->thd->variables.optimizer_full_scan && + !(join->select_options & SELECT_DESCRIBE)) { + my_error(ER_FULL_SCAN_DISABLED, MYF(0)); + DBUG_RETURN(TRUE); + } } } if (!table->no_keyread) diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 15480e1848b4..ee1c65de1eab 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -2608,6 +2608,12 @@ static Sys_var_mybool Sys_optimizer_force_index_for_range( SESSION_VAR(optimizer_force_index_for_range), CMD_LINE(OPT_ARG), DEFAULT(FALSE)); +static Sys_var_mybool Sys_optimizer_full_scan( + "optimizer_full_scan", + "Enable full table and index scans.", + SESSION_VAR(optimizer_full_scan), + CMD_LINE(OPT_ARG), DEFAULT(TRUE)); + static const char *optimizer_switch_names[]= { "index_merge", "index_merge_union", "index_merge_sort_union",