From b614d58b0017dea49e43ec09bf8e3a11e70e8af0 Mon Sep 17 00:00:00 2001 From: Manuel Ung Date: Mon, 25 Mar 2019 13:35:07 -0700 Subject: [PATCH] FB8-172: Add variable to disable full table/index scans (#970) (#970) Summary: Jira issue: https://jira.percona.com/browse/FB8-172 Reference Patch: https://github.com/facebook/mysql-5.6/commit/b90e801 Reference Patch: https://github.com/facebook/mysql-5.6/commit/ecef4b2 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. EXPLAIN queries with derived tables do not populate select_options in the JOIN structure properly. This means that we could error if we tried to run an explain on a query with derived tables. Instead of reading from the JOIN struct, read from the LEX struct on the THD, as this is where the flag is original set on during query parsing. This bug also means that in upstream, we increment some status variables tracking full table scans despite the fact that only an explain statement was done. This seems to have been fixed in 8.0 though. Pull Request resolved: https://github.com/facebook/mysql-5.6/pull/970 Reviewed By: lloyd Differential Revision: D14567846 Pulled By: lth --- mysql-test/r/mysqld--help-notwin.result | 4 + mysql-test/r/opt_hints_set_var.result | 20 ++- mysql-test/r/optimizer_full_scan.result | 116 ++++++++++++++++++ .../r/optimizer_full_scan_basic.result | 93 ++++++++++++++ .../sys_vars/t/optimizer_full_scan_basic.test | 102 +++++++++++++++ mysql-test/t/opt_hints_set_var.test | 12 +- mysql-test/t/optimizer_full_scan.test | 64 ++++++++++ share/messages_to_clients.txt | 4 +- sql/sql_select.cc | 5 + sql/sys_vars.cc | 5 + sql/system_variables.h | 1 + 11 files changed, 418 insertions(+), 8 deletions(-) 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.result b/mysql-test/r/mysqld--help-notwin.result index 7e9b00ae190b..2d75dad4dc30 100644 --- a/mysql-test/r/mysqld--help-notwin.result +++ b/mysql-test/r/mysqld--help-notwin.result @@ -878,6 +878,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-max-subgraph-pairs=# Maximum depth of subgraph pairs a query can have before the hypergraph join optimizer starts reducing the search @@ -2608,6 +2611,7 @@ old FALSE old-alter-table FALSE old-style-user-limits FALSE optimizer-force-index-for-range FALSE +optimizer-full-scan TRUE 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 e9b0d309dfc7..e05b3064d091 100644 --- a/mysql-test/r/opt_hints_set_var.result +++ b/mysql-test/r/opt_hints_set_var.result @@ -466,18 +466,32 @@ id select_type table partitions type possible_keys key key_len ref rows filtered 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); +EXPLAIN SELECT /*+ SET_VAR(optimizer_force_index_for_range=ON) */ 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"); +Note 1003 /* select#1 */ select /*+ SET_VAR(optimizer_force_index_for_range='ON') */ distinct `test`.`t1`.`a` AS `a` from `test`.`t1` FORCE INDEX (PRIMARY) +EXPLAIN SELECT a FROM t1 IGNORE INDEX (PRIMARY) WHERE a IN (1, 2, 3) AND b IN (10, 20); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 NULL ALL NULL NULL NULL NULL 4 25.00 Using where +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` IGNORE INDEX (PRIMARY) where ((`test`.`t1`.`a` in (1,2,3)) and (`test`.`t1`.`b` in (10,20))) +SELECT /*+ SET_VAR(optimizer_full_scan=OFF) */ a FROM t1 IGNORE INDEX (PRIMARY) WHERE a IN (1, 2, 3) AND b IN (10, 20); +ERROR HY000: Full table/index scan is disabled +CALL test_hint("SET_VAR(optimizer_force_index_for_range=ON)", "optimizer_force_index_for_range"); +VARIABLE_VALUE +OFF +VARIABLE_VALUE +ON VARIABLE_VALUE OFF +CALL test_hint("SET_VAR(optimizer_full_scan=OFF)", "optimizer_full_scan"); VARIABLE_VALUE ON VARIABLE_VALUE OFF +VARIABLE_VALUE +ON DROP TABLE t1, t2, t3; CREATE TABLE t1 ( diff --git a/mysql-test/r/optimizer_full_scan.result b/mysql-test/r/optimizer_full_scan.result new file mode 100644 index 000000000000..1585ef74c71b --- /dev/null +++ b/mysql-test/r/optimizer_full_scan.result @@ -0,0 +1,116 @@ +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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL ALL NULL NULL NULL NULL # 100.00 NULL +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i`,`test`.`t`.`j` AS `j` from `test`.`t` +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 i FROM t FORCE INDEX (i); +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t NULL index NULL i 5 NULL # 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select `test`.`t`.`i` AS `i` from `test`.`t` FORCE INDEX (`i`) +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 partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE a NULL ALL i NULL NULL NULL # 100.00 NULL +1 SIMPLE b NULL ALL i NULL NULL NULL # 33.33 Using where; Using join buffer (hash join) +Warnings: +Note 1003 /* select#1 */ select `test`.`a`.`i` AS `i`,`test`.`a`.`j` AS `j`,`test`.`b`.`i` AS `i`,`test`.`b`.`j` AS `j` from `test`.`t` `a` join `test`.`t` `b` where (`test`.`b`.`i` = `test`.`a`.`i`) +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 2 1 1 +1 1 1 1 +1 2 1 2 +1 1 1 2 +2 2 2 1 +2 1 2 1 +2 2 2 2 +2 1 2 2 +3 2 3 1 +3 1 3 1 +3 2 3 2 +3 1 3 2 +EXPLAIN SELECT * FROM t a STRAIGHT_JOIN t b WHERE a.i = 10; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 SIMPLE a NULL ref i i 5 const # 100.00 NULL +1 SIMPLE b NULL ALL NULL NULL NULL NULL # 100.00 Using join buffer (hash join) +Warnings: +Note 1003 /* select#1 */ select `test`.`a`.`i` AS `i`,`test`.`a`.`j` AS `j`,`test`.`b`.`i` AS `i`,`test`.`b`.`j` AS `j` from `test`.`t` `a` straight_join `test`.`t` `b` where (`test`.`a`.`i` = 10) +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 +SET @sql_mode_session = @@session.sql_mode; +SET SESSION sql_mode = ''; +EXPLAIN SELECT * FROM (SELECT * FROM t GROUP BY i) a GROUP BY i; +id select_type table partitions type possible_keys key key_len ref rows filtered Extra +1 PRIMARY NULL ALL NULL NULL NULL NULL # 100.00 Using temporary +2 DERIVED t NULL index i i 5 NULL # 100.00 NULL +Warnings: +Note 1003 /* select#1 */ select `a`.`i` AS `i`,`a`.`j` AS `j` from (/* select#2 */ select `test`.`t`.`i` AS `i`,`test`.`t`.`j` AS `j` from `test`.`t` group by `test`.`t`.`i`) `a` group by `a`.`i` +SET SESSION sql_mode = @sql_mode_session; +# 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 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))) +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 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))) +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; 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..f3c258f1efa7 --- /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 performance_schema.global_variables WHERE VARIABLE_NAME='optimizer_full_scan'; +count(VARIABLE_VALUE) +1 +SELECT IF(@@session.optimizer_full_scan, "ON", "OFF") = VARIABLE_VALUE +FROM performance_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 performance_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..5a06ff384162 --- /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 performance_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 performance_schema.session_variables +WHERE VARIABLE_NAME='optimizer_full_scan'; +SELECT @@session.optimizer_full_scan; +SELECT VARIABLE_VALUE +FROM performance_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/opt_hints_set_var.test b/mysql-test/t/opt_hints_set_var.test index aed075e26a0f..92a428ba1743 100644 --- a/mysql-test/t/opt_hints_set_var.test +++ b/mysql-test/t/opt_hints_set_var.test @@ -259,12 +259,18 @@ 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 +# Testing optimizer_force_index_for_range, optimizer_full_scan variables 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); +EXPLAIN SELECT /*+ SET_VAR(optimizer_force_index_for_range=ON) */ DISTINCT a FROM t1 FORCE INDEX (PRIMARY); -CALL test_hint("SET_VAR(optimizer_force_index_for_range=1)", "optimizer_force_index_for_range"); +EXPLAIN SELECT a FROM t1 IGNORE INDEX (PRIMARY) WHERE a IN (1, 2, 3) AND b IN (10, 20); + +--error ER_FULL_SCAN_DISABLED +SELECT /*+ SET_VAR(optimizer_full_scan=OFF) */ a FROM t1 IGNORE INDEX (PRIMARY) WHERE a IN (1, 2, 3) AND b IN (10, 20); + +CALL test_hint("SET_VAR(optimizer_force_index_for_range=ON)", "optimizer_force_index_for_range"); +CALL test_hint("SET_VAR(optimizer_full_scan=OFF)", "optimizer_full_scan"); DROP TABLE t1, t2, t3; diff --git a/mysql-test/t/optimizer_full_scan.test b/mysql-test/t/optimizer_full_scan.test new file mode 100644 index 000000000000..6fdbb02e9cec --- /dev/null +++ b/mysql-test/t/optimizer_full_scan.test @@ -0,0 +1,64 @@ +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 10 # +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 10 # +EXPLAIN SELECT i 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 10 # +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 10 # +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; + +SET @sql_mode_session = @@session.sql_mode; +SET SESSION sql_mode = ''; # remove ONLY_FULL_GROUP_BY +--replace_column 10 # +EXPLAIN SELECT * FROM (SELECT * FROM t GROUP BY i) a GROUP BY i; +SET SESSION sql_mode = @sql_mode_session; + +--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 10 # +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 10 # +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; diff --git a/share/messages_to_clients.txt b/share/messages_to_clients.txt index fac23c596199..95ea0f025a3e 100644 --- a/share/messages_to_clients.txt +++ b/share/messages_to_clients.txt @@ -10232,8 +10232,8 @@ ER_PLACEHOLDER_50075 ER_PLACEHOLDER_50076 eng "Placeholder" -ER_PLACEHOLDER_50077 - eng "Placeholder" +ER_FULL_SCAN_DISABLED + eng "Full table/index scan is disabled" ER_CF_DROPPED eng "Column family ('%s') is being dropped." diff --git a/sql/sql_select.cc b/sql/sql_select.cc index a7f53abec64b..4e51568ac9de 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3387,6 +3387,11 @@ bool make_join_readinfo(JOIN *join, uint no_jbuf_after) { if (statistics) join->thd->inc_status_select_range_check(); } else { if (statistics) { + /* Block full table/index scans, if optimizer_full_scan is off. */ + if (!join->thd->variables.optimizer_full_scan) { + my_error(ER_FULL_SCAN_DISABLED, MYF(0)); + return true; + } if (i == join->const_tables) join->thd->inc_status_select_scan(); else diff --git a/sql/sys_vars.cc b/sql/sys_vars.cc index 92ed619376bd..47038afff142 100644 --- a/sql/sys_vars.cc +++ b/sql/sys_vars.cc @@ -3444,6 +3444,11 @@ static Sys_var_bool Sys_optimizer_force_index_for_range( HINT_UPDATEABLE SESSION_VAR(optimizer_force_index_for_range), CMD_LINE(OPT_ARG), DEFAULT(false)); +static Sys_var_bool Sys_optimizer_full_scan( + "optimizer_full_scan", "Enable full table and index scans.", + HINT_UPDATEABLE SESSION_VAR(optimizer_full_scan), CMD_LINE(OPT_ARG), + DEFAULT(true)); + /// @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 5e91a7456b0d..b5c8240c9551 100644 --- a/sql/system_variables.h +++ b/sql/system_variables.h @@ -245,6 +245,7 @@ struct System_variables { long optimizer_trace_limit; ulong optimizer_trace_max_mem_size; bool optimizer_force_index_for_range; + 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;