The optimizer_switch system
variable enables control over optimizer behavior. Its value is a
set of flags, each of which has a value of on
or off to indicate whether the corresponding
optimizer behavior is enabled or disabled. This variable has
global and session values and can be changed at runtime. The
global default can be set at server startup.
To see the current set of optimizer flags, select the variable value:
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=on,
index_merge_sort_union=on,
index_merge_intersection=on,
engine_condition_pushdown=on,
index_condition_pushdown=on,
mrr=on,mrr_cost_based=on,
block_nested_loop=on,batched_key_access=off,
materialization=on,semijoin=on,loosescan=on,
firstmatch=on,duplicateweedout=on,
subquery_materialization_cost_based=on,
use_index_extensions=on,
condition_fanout_filter=on,derived_merge=on,
prefer_ordering_index=on
To change the value of
optimizer_switch, assign a
value consisting of a comma-separated list of one or more
commands:
SET [GLOBAL|SESSION] optimizer_switch='command[,command]...';
Each command value should have one of
the forms shown in the following table.
| Command Syntax | Meaning |
|---|---|
default |
Reset every optimization to its default value |
|
Set the named optimization to its default value |
|
Disable the named optimization |
|
Enable the named optimization |
The order of the commands in the value does not matter, although
the default command is executed first if
present. Setting an opt_name flag to
default sets it to whichever of
on or off is its default
value. Specifying any given opt_name
more than once in the value is not permitted and causes an
error. Any errors in the value cause the assignment to fail with
an error, leaving the value of
optimizer_switch unchanged.
The following list describes the permissible
opt_name flag names, grouped by
optimization strategy:
Batched Key Access Flags
batched_key_access(defaultoff)Controls use of BKA join algorithm.
For
batched_key_accessto have any effect when set toon, themrrflag must also beon. Currently, the cost estimation for MRR is too pessimistic. Hence, it is also necessary formrr_cost_basedto beofffor BKA to be used.For more information, see Section 8.2.1.11, “Block Nested-Loop and Batched Key Access Joins”.
Block Nested-Loop Flags
block_nested_loop(defaulton)Controls use of BNL join algorithm.
For more information, see Section 8.2.1.11, “Block Nested-Loop and Batched Key Access Joins”.
Condition Filtering Flags
condition_fanout_filter(defaulton)Controls use of condition filtering.
For more information, see Section 8.2.1.12, “Condition Filtering”.
Derived Table Merging Flags
derived_merge(defaulton)Controls merging of derived tables and views into outer query block.
The
derived_mergeflag controls whether the optimizer attempts to merge derived tables and view references into the outer query block, assuming that no other rule prevents merging; for example, anALGORITHMdirective for a view takes precedence over thederived_mergesetting. By default, the flag isonto enable merging.For more information, see Section 8.2.2.4, “Optimizing Derived Tables and View References with Merging or Materialization”.
Engine Condition Pushdown Flags
engine_condition_pushdown(defaulton)Controls engine condition pushdown.
For more information, see Section 8.2.1.4, “Engine Condition Pushdown Optimization”.
Index Condition Pushdown Flags
index_condition_pushdown(defaulton)Controls index condition pushdown.
For more information, see Section 8.2.1.5, “Index Condition Pushdown Optimization”.
Index Extensions Flags
use_index_extensions(defaulton)Controls use of index extensions.
For more information, see Section 8.3.9, “Use of Index Extensions”.
Index Merge Flags
index_merge(defaulton)Controls all Index Merge optimizations.
index_merge_intersection(defaulton)Controls the Index Merge Intersection Access optimization.
index_merge_sort_union(defaulton)Controls the Index Merge Sort-Union Access optimization.
index_merge_union(defaulton)Controls the Index Merge Union Access optimization.
For more information, see Section 8.2.1.3, “Index Merge Optimization”.
Limit Optimization Flags
prefer_ordering_index(defaulton)Controls whether, in the case of a query having an
ORDER BYorGROUP BYwith aLIMITclause, the optimizer tries to use an ordered index instead of an unordered index, a filesort, or some other optimization. This optimzation is performed by default whenever the optimizer determines that using it would allow for faster execution of the query.Because the algorithm that makes this determination cannot handle every conceivable case (due in part to the assumption that the distribution of data is always more or less uniform), there are cases in which this optimization may not be desirable. Prior to MySQL 5.7.33, it ws not possible to disable this optimization, but in MySQL 5.7.33 and later, while it remains the default behavior, it can be disabled by setting the
prefer_ordering_indexflag tooff.
For more information and examples, see Section 8.2.1.17, “LIMIT Query Optimization”.
Multi-Range Read Flags
mrr(defaulton)Controls the Multi-Range Read strategy.
mrr_cost_based(defaulton)Controls use of cost-based MRR if
mrr=on.
For more information, see Section 8.2.1.10, “Multi-Range Read Optimization”.
Semijoin Flags
duplicateweedout(defaulton)Controls the semijoin Duplicate Weedout strategy.
firstmatch(defaulton)Controls the semijoin FirstMatch strategy.
loosescan(defaulton)Controls the semijoin LooseScan strategy (not to be confused with Loose Index Scan for
GROUP BY).semijoin(defaulton)Controls all semijoin strategies.
The
semijoin,firstmatch,loosescan, andduplicateweedoutflags enable control over semijoin strategies. Thesemijoinflag controls whether semijoins are used. If it is set toon, thefirstmatchandloosescanflags enable finer control over the permitted semijoin strategies.If the
duplicateweedoutsemijoin strategy is disabled, it is not used unless all other applicable strategies are also disabled.If
semijoinandmaterializationare bothon, semijoins also use materialization where applicable. These flags areonby default.For more information, see Section 8.2.2.1, “Optimizing Subqueries, Derived Tables, and View References with Semijoin Transformations”.
Subquery Materialization Flags
materialization(defaulton)Controls materialization (including semijoin materialization).
subquery_materialization_cost_based(defaulton)Use cost-based materialization choice.
The
materializationflag controls whether subquery materialization is used. Ifsemijoinandmaterializationare bothon, semijoins also use materialization where applicable. These flags areonby default.The
subquery_materialization_cost_basedflag enables control over the choice between subquery materialization andIN-to-EXISTSsubquery transformation. If the flag ison(the default), the optimizer performs a cost-based choice between subquery materialization andIN-to-EXISTSsubquery transformation if either method could be used. If the flag isoff, the optimizer chooses subquery materialization overIN-to-EXISTSsubquery transformation.For more information, see Section 8.2.2, “Optimizing Subqueries, Derived Tables, and View References”.
When you assign a value to
optimizer_switch, flags that
are not mentioned keep their current values. This makes it
possible to enable or disable specific optimizer behaviors in a
single statement without affecting other behaviors. The
statement does not depend on what other optimizer flags exist
and what their values are. Suppose that all Index Merge
optimizations are enabled:
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=on,
index_merge_sort_union=on,
index_merge_intersection=on,
engine_condition_pushdown=on,
index_condition_pushdown=on,
mrr=on,mrr_cost_based=on,
block_nested_loop=on,batched_key_access=off,
materialization=on,semijoin=on,loosescan=on,
firstmatch=on,duplicateweedout=on,
subquery_materialization_cost_based=on,
use_index_extensions=on,
condition_fanout_filter=on,derived_merge=on,
prefer_ordering_index=onIf the server is using the Index Merge Union or Index Merge Sort-Union access methods for certain queries and you want to check whether the optimizer performs better without them, set the variable value like this:
mysql> SET optimizer_switch='index_merge_union=off,index_merge_sort_union=off';
mysql> SELECT @@optimizer_switch\G
*************************** 1. row ***************************
@@optimizer_switch: index_merge=on,index_merge_union=off,
index_merge_sort_union=off,
index_merge_intersection=on,
engine_condition_pushdown=on,
index_condition_pushdown=on,
mrr=on,mrr_cost_based=on,
block_nested_loop=on,batched_key_access=off,
materialization=on,semijoin=on,loosescan=on,
firstmatch=on,duplicateweedout=on,
subquery_materialization_cost_based=on,
use_index_extensions=on,
condition_fanout_filter=on,derived_merge=on,
prefer_ordering_index=on