From ac1b73da03be066d5788a355b0249d7a57c3968b Mon Sep 17 00:00:00 2001 From: Yiding Cui Date: Sun, 28 Jun 2020 03:39:10 +0800 Subject: [PATCH 1/8] SQL Tuning: add the page `blacklist-control-plan.md` --- TOC.md | 1 + blacklist-control-plan.md | 243 ++++++++++++++++++++++++++++++++++++++ 2 files changed, 244 insertions(+) create mode 100644 blacklist-control-plan.md diff --git a/TOC.md b/TOC.md index 2917937ac066c..c5ca673fed5e7 100644 --- a/TOC.md +++ b/TOC.md @@ -106,6 +106,7 @@ + [Optimizer Hints](/optimizer-hints.md) + [SQL Plan Management](/sql-plan-management.md) + [Access Tables Using `IndexMerge`](/index-merge.md) + + [The Blacklist of Optimization Rules and Expression Pushdown](/blacklist-control-plan.md) + Tutorials + [Geo-Redundant Deployment](/geo-redundancy-deployment.md) + Best Practices diff --git a/blacklist-control-plan.md b/blacklist-control-plan.md new file mode 100644 index 0000000000000..e6b3ee797421c --- /dev/null +++ b/blacklist-control-plan.md @@ -0,0 +1,243 @@ +--- +title: The Blacklist of Optimization Rules and Expression Pushdown +summary: Learn about the blacklist to control the optimization rules and the behavior of expression pushdown. +category: performance +--- + +# The Blacklist of Optimization Rules and Expression Pushdown + +This document introduces how we use the blacklist of optimization rules and the blacklist of expression pushdown to control the behavior of TiDB. + +## The Blacklist of Optimization Rules + +### Important Optimization Rules + +|**Optimization Rule**|**Rule Name**|**Description**| +| :--- | :--- | :--- | +| Column Pruning | column_prune | One executor will prune the column if it's not needed by the upper executor | +| Decorrelate Subquery | decorrelate | Try to rewrite the correlated subquery to non-correlated join or aggregation | +| Aggregation Elimination | aggregation_eliminate | Try to remove some unnecessary aggregations | +| Projection Elimination | projection_eliminate | Remove unnecessary projects | +| Max/Min Elimination | max_min_eliminate | Rewrite some max/min function in aggregation to the form `order by` + `limit 1` | +| Predicate Pushdown | predicate_push_down | Try to push predicates to the executor that is closer to the data source | +| Outer Join Elimination | outer_join_eliminate | Try to convert the left/right join to inner join | +| Partition Pruning | partition_processor | Pruning partitions which are rejected by the predicates and rewrite to the form `UnionAll + Partition Datasource` | +| Aggregation Pushdown | aggregation_push_down| Try to push aggregations down to their children | +| TopN Pushdown | topn_push_down | Try to push the topn to where is closer to the data source | +| Join Reorder | join_reorder | Decide the order of multi-table joins | + +### Disable Optimization Rules + +We can use the **Blacklist of Optimization Rules** to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. + +#### Usage + +> **Note:** +> +> All the following operations need the `super privilege` privilege of the database. Each optimization rule has a name. e.g. the name of column pruning is `column_prune`. The names of all optimization rules can be found in the second column of the table [Important Optimization Rules](#Important_Optimization_Rules). + +- If you want to disable some rules, you can write its name to the table `mysql.opt_rule_blacklist`. e.g. + + {{< copyable "sql" >}} + + ```sql + insert into mysql.opt_rule_blacklist values("join_reorder"), ("topn_push_down"); + ``` + + Executing the following SQL statement can make the above operation take effect immediately. Including old connections of the corresponding TiDB Server: + + {{< copyable "sql" >}} + + ```sql + admin reload opt_rule_blacklist; + ``` + + > **Note:** + > + > `admin reload opt_rule_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. + +- If you want to re-enable some rules, delete the corresponding data in the table, and then run `admin reload` statement: + + {{< copyable "sql" >}} + + ```sql + delete from mysql.opt_rule_blacklist where name in ("join_reoder", "topn_push_down"); + admin reload opt_rule_blacklist; + ``` + +## The Blacklist of Expression Pushdown + +**The Blacklist of Expression Pushdown** is one way to tuning the expression pushdown, mainly used to disable some expression of some specific data types. + +### Expressions which are supported to be pushed down + +| Expression Classification | Concrete Operations | +| :-------------- | :------------------------------------- | +| [Logical Operations](/functions-and-operators/operators.md#logical-operators) | AND (&&), OR (||), NOT (!) | +| [Comparison functions and operators](#comparison-functions-and-operators) | <, <=, =, != (`<>`), >, >=, [`<=>`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#operator_equal-to), [`IN()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_in), IS NULL, LIKE, IS TRUE, IS FALSE, [`COALESCE()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_coalesce) | +| [Numberic functions and operators](/functions-and-operators/numeric-functions-and-operators.md) | +, -, *, /, [`ABS()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_abs), [`CEIL()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceil), [`CEILING()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceiling), [`FLOOR()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_floor) | +| [Control flow functions](/functions-and-operators/control-flow-functions.md) | [`CASE`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#operator_case), [`IF()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_if), [`IFNULL()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_ifnull) | +| [JSON functions](/functions-and-operators/json-functions.md) | [JSON_TYPE(json_val)][json_type],
[JSON_EXTRACT(json_doc, path[, path] ...)][json_extract],
[JSON_UNQUOTE(json_val)][json_unquote],
[JSON_OBJECT(key, val[, key, val] ...)][json_object],
[JSON_ARRAY([val[, val] ...])][json_array],
[JSON_MERGE(json_doc, json_doc[, json_doc] ...)][json_merge],
[JSON_SET(json_doc, path, val[, path, val] ...)][json_set],
[JSON_INSERT(json_doc, path, val[, path, val] ...)][json_insert],
[JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace],
[JSON_REMOVE(json_doc, path[, path] ...)][json_remove] | +| [Date and time functions](/functions-and-operators/date-and-time-functions.md) | [`DATE_FORMAT()`](https://dev.mysql.com/doc/refman/5.7/en/date-and-time-functions.html#function_date-format) | + +### Disable the pushdown of specific expression + +When we got wrong results due to the expression pushdown, use the blacklist can make a quick recovery for the business. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. + +The schema of `mysql.expr_pushdown_blacklist` is shown as below: + +{{< copyable "sql" >}} + +```sql +desc mysql.expr_pushdown_blacklist; +``` + +```sql ++------------+--------------+------+------+-------------------+-------+ +| Field | Type | Null | Key | Default | Extra | ++------------+--------------+------+------+-------------------+-------+ +| name | char(100) | NO | | NULL | | +| store_type | char(100) | NO | | tikv,tiflash,tidb | | +| reason | varchar(200) | YES | | NULL | | ++------------+--------------+------+------+-------------------+-------+ +3 rows in set (0.00 sec) +``` + +Here is the description of each field: + ++ `name`: The name of expression that is disabled to be pushed down. ++ `store_type`: To specify the component you don't want the expression to be pushed down. Three components `tidb`, `tikv`, and `tiflash` are available. The `store_type` is case-insensitive. Use the comma to divide each component if more than one component is specified. + - The `store_type` `tidb` decides whether the expression can be executed in other TiDB Server when reading the TiDB memory table. + - The `store_type` `tikv` decides whether the expression can be executed in TiKV Server's Coprocessor component. + - The `store_type` `tiflash` decides whether the expression can be executed in TiFlash Server's Coprocessor component. ++ `reason`: To record the reason why this expression is added to the blacklist. + +### Usage + +#### Add to the blacklist + +Using the following procedures if you want to add one or more expressions to the blacklist: + +1. Insert the corresponding function name or operator name and the set of components you want to disable the pushdown to the table `mysql.expr_pushdown_blacklist`. + +2. Execute `admin reload expr_pushdown_blacklist`. + +### Remove from the blacklist + +Using the following procedures if you want to remove one or more expressions from the blacklist: + +1. Delete the corresponding function name or operator name and the set of components you want to disable the pushdown from the table `mysql.expr_pushdown_blacklist`. + +2. Execute `admin reload expr_pushdown_blacklist`. + +> **Note:** +> +> `admin reload expr_pushdown_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. + +## Example of the Expression Blacklist + +The following example first adds the operator `<` and `>` to the blacklist then removes the operator `>` from the blacklist. + +Whether the blacklist takes effect can be observed in the `EXPLAIN` result(See [SQL Tuning with `EXPLAIN`](/query-execution-plan.md)). + +1. The predicates `a < 2` and `a > 2` in the `WHERE` clause of the following SQL statement can be pushed down to TiKV. + + {{< copyable "sql" >}} + + ```sql + explain select * from t where a < 2 and a > 2; + ``` + + ```sql + +-------------------------+----------+-----------+---------------+------------------------------------+ + | id | estRows | task | access object | operator info | + +-------------------------+----------+-----------+---------------+------------------------------------+ + | TableReader_7 | 0.00 | root | | data:Selection_6 | + | └─Selection_6 | 0.00 | cop[tikv] | | gt(ssb_1.t.a, 2), lt(ssb_1.t.a, 2) | + | └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | + +-------------------------+----------+-----------+---------------+------------------------------------+ + 3 rows in set (0.00 sec) + ``` + +2. Insert the expression to the table `mysql.expr_pushdown_blacklist` and execute `admin reload expr_pushdown_blacklist`. + + {{< copyable "sql" >}} + + ```sql + insert into mysql.expr_pushdown_blacklist values('<','tikv',''), ('>','tikv',''); + ``` + + ```sql + Query OK, 2 rows affected (0.01 sec) + Records: 2 Duplicates: 0 Warnings: 0 + ``` + + {{< copyable "sql" >}} + + ```sql + admin reload expr_pushdown_blacklist; + ``` + + ```sql + Query OK, 0 rows affected (0.00 sec) + ``` + +3. Observe the execution plan again and you will find that both the operator `<` and `>` are not pushed down to TiKV Coprocessor. + + {{< copyable "sql" >}} + + ```sql + explain select * from t where a < 2 and a > 2; + ``` + + ```sql + +-------------------------+----------+-----------+---------------+------------------------------------+ + | id | estRows | task | access object | operator info | + +-------------------------+----------+-----------+---------------+------------------------------------+ + | Selection_7 | 10000.00 | root | | gt(ssb_1.t.a, 2), lt(ssb_1.t.a, 2) | + | └─TableReader_6 | 10000.00 | root | | data:TableFullScan_5 | + | └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | + +-------------------------+----------+-----------+---------------+------------------------------------+ + 3 rows in set (0.00 sec) + ``` + +4. Remove one expression(here is `>`) from the blacklist and execute `admin reload expr_pushdown_blacklist`. + + {{< copyable "sql" >}} + + ```sql + delete from mysql.expr_pushdown_blacklist where name = '>'; + ``` + + ```sql + Query OK, 1 row affected (0.01 sec) + ``` + + {{< copyable "sql" >}} + + ```sql + admin reload expr_pushdown_blacklist; + ``` + + ```sql + Query OK, 0 rows affected (0.00 sec) + +5. Observe the execution plan again and you will find that `<` is not pushed down while `>` is not pushed down to TiKV Coprocessor. + + {{< copyable "sql" >}} + + ```sql + explain select * from t where a < 2 and a > 2; + ``` + + ```sql + +---------------------------+----------+-----------+---------------+--------------------------------+ + | id | estRows | task | access object | operator info | + +---------------------------+----------+-----------+---------------+--------------------------------+ + | Selection_8 | 0.00 | root | | lt(ssb_1.t.a, 2) | + | └─TableReader_7 | 0.00 | root | | data:Selection_6 | + | └─Selection_6 | 0.00 | cop[tikv] | | gt(ssb_1.t.a, 2) | + | └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | + +---------------------------+----------+-----------+---------------+--------------------------------+ + 4 rows in set (0.00 sec) + ``` \ No newline at end of file From b7bfd633062e737d40e6950cea8dbfe48d47e41d Mon Sep 17 00:00:00 2001 From: Yiding Cui Date: Mon, 29 Jun 2020 13:44:23 +0800 Subject: [PATCH 2/8] rename blacklist to blocklist --- TOC.md | 2 +- ...ntrol-plan.md => blocklist-control-plan.md | 34 +++++++++---------- 2 files changed, 18 insertions(+), 18 deletions(-) rename blacklist-control-plan.md => blocklist-control-plan.md (93%) diff --git a/TOC.md b/TOC.md index c5ca673fed5e7..e1cd14ed0d1c1 100644 --- a/TOC.md +++ b/TOC.md @@ -106,7 +106,7 @@ + [Optimizer Hints](/optimizer-hints.md) + [SQL Plan Management](/sql-plan-management.md) + [Access Tables Using `IndexMerge`](/index-merge.md) - + [The Blacklist of Optimization Rules and Expression Pushdown](/blacklist-control-plan.md) + + [The Blacklist of Optimization Rules and Expression Pushdown](/blocklist-control-plan.md) + Tutorials + [Geo-Redundant Deployment](/geo-redundancy-deployment.md) + Best Practices diff --git a/blacklist-control-plan.md b/blocklist-control-plan.md similarity index 93% rename from blacklist-control-plan.md rename to blocklist-control-plan.md index e6b3ee797421c..0faec4f18f19c 100644 --- a/blacklist-control-plan.md +++ b/blocklist-control-plan.md @@ -1,14 +1,14 @@ --- -title: The Blacklist of Optimization Rules and Expression Pushdown -summary: Learn about the blacklist to control the optimization rules and the behavior of expression pushdown. +title: The Blocklist of Optimization Rules and Expression Pushdown +summary: Learn about the blocklist to control the optimization rules and the behavior of expression pushdown. category: performance --- -# The Blacklist of Optimization Rules and Expression Pushdown +# The Blocklist of Optimization Rules and Expression Pushdown -This document introduces how we use the blacklist of optimization rules and the blacklist of expression pushdown to control the behavior of TiDB. +This document introduces how we use the blocklist of optimization rules and the blocklist of expression pushdown to control the behavior of TiDB. -## The Blacklist of Optimization Rules +## The Blocklist of Optimization Rules ### Important Optimization Rules @@ -28,7 +28,7 @@ This document introduces how we use the blacklist of optimization rules and the ### Disable Optimization Rules -We can use the **Blacklist of Optimization Rules** to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. +We can use the **Blocklist of Optimization Rules** to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. #### Usage @@ -65,9 +65,9 @@ We can use the **Blacklist of Optimization Rules** to disable some of them if so admin reload opt_rule_blacklist; ``` -## The Blacklist of Expression Pushdown +## The Blocklist of Expression Pushdown -**The Blacklist of Expression Pushdown** is one way to tuning the expression pushdown, mainly used to disable some expression of some specific data types. +**The Blocklist of Expression Pushdown** is one way to tuning the expression pushdown, mainly used to disable some expression of some specific data types. ### Expressions which are supported to be pushed down @@ -82,7 +82,7 @@ We can use the **Blacklist of Optimization Rules** to disable some of them if so ### Disable the pushdown of specific expression -When we got wrong results due to the expression pushdown, use the blacklist can make a quick recovery for the business. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. +When we got wrong results due to the expression pushdown, use the blocklist can make a quick recovery for the business. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. The schema of `mysql.expr_pushdown_blacklist` is shown as below: @@ -110,21 +110,21 @@ Here is the description of each field: - The `store_type` `tidb` decides whether the expression can be executed in other TiDB Server when reading the TiDB memory table. - The `store_type` `tikv` decides whether the expression can be executed in TiKV Server's Coprocessor component. - The `store_type` `tiflash` decides whether the expression can be executed in TiFlash Server's Coprocessor component. -+ `reason`: To record the reason why this expression is added to the blacklist. ++ `reason`: To record the reason why this expression is added to the blocklist. ### Usage -#### Add to the blacklist +#### Add to the blocklist -Using the following procedures if you want to add one or more expressions to the blacklist: +Using the following procedures if you want to add one or more expressions to the blocklist: 1. Insert the corresponding function name or operator name and the set of components you want to disable the pushdown to the table `mysql.expr_pushdown_blacklist`. 2. Execute `admin reload expr_pushdown_blacklist`. -### Remove from the blacklist +### Remove from the blocklist -Using the following procedures if you want to remove one or more expressions from the blacklist: +Using the following procedures if you want to remove one or more expressions from the blocklist: 1. Delete the corresponding function name or operator name and the set of components you want to disable the pushdown from the table `mysql.expr_pushdown_blacklist`. @@ -134,11 +134,11 @@ Using the following procedures if you want to remove one or more expressions fro > > `admin reload expr_pushdown_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. -## Example of the Expression Blacklist +## Example of the Expression Blocklist -The following example first adds the operator `<` and `>` to the blacklist then removes the operator `>` from the blacklist. +The following example first adds the operator `<` and `>` to the blocklist then removes the operator `>` from the blocklist. -Whether the blacklist takes effect can be observed in the `EXPLAIN` result(See [SQL Tuning with `EXPLAIN`](/query-execution-plan.md)). +Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [SQL Tuning with `EXPLAIN`](/query-execution-plan.md)). 1. The predicates `a < 2` and `a > 2` in the `WHERE` clause of the following SQL statement can be pushed down to TiKV. From 59273be41cbdf70a49c477e1ba1743a3b7ff8c9f Mon Sep 17 00:00:00 2001 From: Yiding Cui Date: Mon, 29 Jun 2020 13:46:20 +0800 Subject: [PATCH 3/8] Update TOC.md Co-authored-by: Feng Liyuan --- TOC.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/TOC.md b/TOC.md index e1cd14ed0d1c1..714a7ce8f7a7f 100644 --- a/TOC.md +++ b/TOC.md @@ -106,7 +106,7 @@ + [Optimizer Hints](/optimizer-hints.md) + [SQL Plan Management](/sql-plan-management.md) + [Access Tables Using `IndexMerge`](/index-merge.md) - + [The Blacklist of Optimization Rules and Expression Pushdown](/blocklist-control-plan.md) + + [The Blocklist of Optimization Rules and Expression Pushdown](/blocklist-control-plan.md) + Tutorials + [Geo-Redundant Deployment](/geo-redundancy-deployment.md) + Best Practices From 2b541bb6b6851a66ab6ddf2fe6e91cc1480388ff Mon Sep 17 00:00:00 2001 From: Yiding Cui Date: Mon, 29 Jun 2020 13:57:41 +0800 Subject: [PATCH 4/8] Update blocklist-control-plan.md Co-authored-by: Feng Liyuan --- blocklist-control-plan.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/blocklist-control-plan.md b/blocklist-control-plan.md index 0faec4f18f19c..5668fb31d20c8 100644 --- a/blocklist-control-plan.md +++ b/blocklist-control-plan.md @@ -201,7 +201,7 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ 3 rows in set (0.00 sec) ``` -4. Remove one expression(here is `>`) from the blacklist and execute `admin reload expr_pushdown_blacklist`. +4. Remove one expression(here is `>`) from the blocklist and execute `admin reload expr_pushdown_blacklist`. {{< copyable "sql" >}} @@ -240,4 +240,4 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ | └─TableFullScan_5 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | +---------------------------+----------+-----------+---------------+--------------------------------+ 4 rows in set (0.00 sec) - ``` \ No newline at end of file + ``` From 8931764743ead308c86c6a61177c5d1f387c67be Mon Sep 17 00:00:00 2001 From: Lilian Lee Date: Tue, 14 Jul 2020 14:06:27 +0800 Subject: [PATCH 5/8] Fix anchor links, optimize wording and format --- blocklist-control-plan.md | 29 +++++++++++++++-------------- 1 file changed, 15 insertions(+), 14 deletions(-) diff --git a/blocklist-control-plan.md b/blocklist-control-plan.md index 5668fb31d20c8..7f0d4b27a8f58 100644 --- a/blocklist-control-plan.md +++ b/blocklist-control-plan.md @@ -1,16 +1,17 @@ --- title: The Blocklist of Optimization Rules and Expression Pushdown summary: Learn about the blocklist to control the optimization rules and the behavior of expression pushdown. -category: performance --- # The Blocklist of Optimization Rules and Expression Pushdown -This document introduces how we use the blocklist of optimization rules and the blocklist of expression pushdown to control the behavior of TiDB. +This document introduces how to use the blocklist of optimization rules and the blocklist of expression pushdown to control the behavior of TiDB. -## The Blocklist of Optimization Rules +## The blocklist of optimization rules -### Important Optimization Rules +The blocklist of optimization rules is one way to tune optimization rules, mainly used to manually disable some optimization rules. + +### Important optimization rules |**Optimization Rule**|**Rule Name**|**Description**| | :--- | :--- | :--- | @@ -26,17 +27,17 @@ This document introduces how we use the blocklist of optimization rules and the | TopN Pushdown | topn_push_down | Try to push the topn to where is closer to the data source | | Join Reorder | join_reorder | Decide the order of multi-table joins | -### Disable Optimization Rules +### Disable optimization rules -We can use the **Blocklist of Optimization Rules** to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. +You can use the blocklist of optimization rules to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. #### Usage > **Note:** > -> All the following operations need the `super privilege` privilege of the database. Each optimization rule has a name. e.g. the name of column pruning is `column_prune`. The names of all optimization rules can be found in the second column of the table [Important Optimization Rules](#Important_Optimization_Rules). +> All the following operations need the `super privilege` privilege of the database. Each optimization rule has a name. e.g. the name of column pruning is `column_prune`. The names of all optimization rules can be found in the second column of the table [Important Optimization Rules](#important-optimization-rules). -- If you want to disable some rules, you can write its name to the table `mysql.opt_rule_blacklist`. e.g. +- If you want to disable some rules, write its name to the table `mysql.opt_rule_blacklist`. e.g. {{< copyable "sql" >}} @@ -65,24 +66,24 @@ We can use the **Blocklist of Optimization Rules** to disable some of them if so admin reload opt_rule_blacklist; ``` -## The Blocklist of Expression Pushdown +## The blocklist of expression pushdown -**The Blocklist of Expression Pushdown** is one way to tuning the expression pushdown, mainly used to disable some expression of some specific data types. +The blocklist of expression pushdown is one way to tune the expression pushdown, mainly used to manually disable some expressions of some specific data types. ### Expressions which are supported to be pushed down | Expression Classification | Concrete Operations | | :-------------- | :------------------------------------- | | [Logical Operations](/functions-and-operators/operators.md#logical-operators) | AND (&&), OR (||), NOT (!) | -| [Comparison functions and operators](#comparison-functions-and-operators) | <, <=, =, != (`<>`), >, >=, [`<=>`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#operator_equal-to), [`IN()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_in), IS NULL, LIKE, IS TRUE, IS FALSE, [`COALESCE()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_coalesce) | +| [Comparison functions and operators](/functions-and-operators/operators.md#comparison-functions-and-operators) | <, <=, =, != (`<>`), >, >=, [`<=>`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#operator_equal-to), [`IN()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_in), IS NULL, LIKE, IS TRUE, IS FALSE, [`COALESCE()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_coalesce) | | [Numberic functions and operators](/functions-and-operators/numeric-functions-and-operators.md) | +, -, *, /, [`ABS()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_abs), [`CEIL()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceil), [`CEILING()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceiling), [`FLOOR()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_floor) | | [Control flow functions](/functions-and-operators/control-flow-functions.md) | [`CASE`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#operator_case), [`IF()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_if), [`IFNULL()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_ifnull) | | [JSON functions](/functions-and-operators/json-functions.md) | [JSON_TYPE(json_val)][json_type],
[JSON_EXTRACT(json_doc, path[, path] ...)][json_extract],
[JSON_UNQUOTE(json_val)][json_unquote],
[JSON_OBJECT(key, val[, key, val] ...)][json_object],
[JSON_ARRAY([val[, val] ...])][json_array],
[JSON_MERGE(json_doc, json_doc[, json_doc] ...)][json_merge],
[JSON_SET(json_doc, path, val[, path, val] ...)][json_set],
[JSON_INSERT(json_doc, path, val[, path, val] ...)][json_insert],
[JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace],
[JSON_REMOVE(json_doc, path[, path] ...)][json_remove] | | [Date and time functions](/functions-and-operators/date-and-time-functions.md) | [`DATE_FORMAT()`](https://dev.mysql.com/doc/refman/5.7/en/date-and-time-functions.html#function_date-format) | -### Disable the pushdown of specific expression +### Disable the pushdown of specific expressions -When we got wrong results due to the expression pushdown, use the blocklist can make a quick recovery for the business. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. +When you get wrong results due to the expression pushdown, using the blocklist can make a quick recovery for the application. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. The schema of `mysql.expr_pushdown_blacklist` is shown as below: @@ -134,7 +135,7 @@ Using the following procedures if you want to remove one or more expressions fro > > `admin reload expr_pushdown_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. -## Example of the Expression Blocklist +## Expression blocklist usage example The following example first adds the operator `<` and `>` to the blocklist then removes the operator `>` from the blocklist. From b0e1ffde42164a803ebb21c4343485ccdec4411b Mon Sep 17 00:00:00 2001 From: lilin90 Date: Tue, 14 Jul 2020 19:44:05 +0800 Subject: [PATCH 6/8] Update wording and add multiple missing links --- blocklist-control-plan.md | 88 +++++++++++++++++++++------------------ 1 file changed, 48 insertions(+), 40 deletions(-) diff --git a/blocklist-control-plan.md b/blocklist-control-plan.md index 7f0d4b27a8f58..277c80c2db99c 100644 --- a/blocklist-control-plan.md +++ b/blocklist-control-plan.md @@ -15,29 +15,29 @@ The blocklist of optimization rules is one way to tune optimization rules, mainl |**Optimization Rule**|**Rule Name**|**Description**| | :--- | :--- | :--- | -| Column Pruning | column_prune | One executor will prune the column if it's not needed by the upper executor | -| Decorrelate Subquery | decorrelate | Try to rewrite the correlated subquery to non-correlated join or aggregation | -| Aggregation Elimination | aggregation_eliminate | Try to remove some unnecessary aggregations | -| Projection Elimination | projection_eliminate | Remove unnecessary projects | -| Max/Min Elimination | max_min_eliminate | Rewrite some max/min function in aggregation to the form `order by` + `limit 1` | -| Predicate Pushdown | predicate_push_down | Try to push predicates to the executor that is closer to the data source | -| Outer Join Elimination | outer_join_eliminate | Try to convert the left/right join to inner join | -| Partition Pruning | partition_processor | Pruning partitions which are rejected by the predicates and rewrite to the form `UnionAll + Partition Datasource` | -| Aggregation Pushdown | aggregation_push_down| Try to push aggregations down to their children | -| TopN Pushdown | topn_push_down | Try to push the topn to where is closer to the data source | -| Join Reorder | join_reorder | Decide the order of multi-table joins | +| Column pruning | column_prune | One operator will prune the column if it is not needed by the upper executor. | +| Decorrelate subquery | decorrelate | Tries to rewrite the correlated subquery to non-correlated join or aggregation. | +| Aggregation elimination | aggregation_eliminate | Tries to remove unnecessary aggregation operators from the execution plan. | +| Projection elimination | projection_eliminate | Removes unnecessary projection operators from the execution plan. | +| Max/Min elimination | max_min_eliminate | Rewrites some max/min functions in aggregation to the `order by` + `limit 1` form. | +| Predicate pushdown | predicate_push_down | Tries to push predicates down to the operator that is closer to the data source. | +| Outer join elimination | outer_join_eliminate | Tries to remove the unnecessary left join or right join from the execution plan. | +| Partition pruning | partition_processor | Prunes partitions which are rejected by the predicates and rewrite partitioned table query to the `UnionAll + Partition Datasource` form. | +| Aggregation pushdown | aggregation_push_down | Tries to push aggregations down to their children. | +| TopN pushdown | topn_push_down | Tries to push the TopN operator to the place closer to the data source. | +| Join reorder | join_reorder | Decides the order of multi-table joins. | ### Disable optimization rules -You can use the blocklist of optimization rules to disable some of them if some rules lead to a sub-optimal execution plan for some special queries. +You can use the blocklist of optimization rules to disable some of them if some rules lead to a sub-optimal execution plan for special queries. #### Usage > **Note:** > -> All the following operations need the `super privilege` privilege of the database. Each optimization rule has a name. e.g. the name of column pruning is `column_prune`. The names of all optimization rules can be found in the second column of the table [Important Optimization Rules](#important-optimization-rules). +> All the following operations need the `super privilege` privilege of the database. Each optimization rule has a name. For example, the name of column pruning is `column_prune`. The names of all optimization rules can be found in the second column of the table [Important Optimization Rules](#important-optimization-rules). -- If you want to disable some rules, write its name to the table `mysql.opt_rule_blacklist`. e.g. +- If you want to disable some rules, write its name to the `mysql.opt_rule_blacklist` table. For example: {{< copyable "sql" >}} @@ -45,7 +45,7 @@ You can use the blocklist of optimization rules to disable some of them if some insert into mysql.opt_rule_blacklist values("join_reorder"), ("topn_push_down"); ``` - Executing the following SQL statement can make the above operation take effect immediately. Including old connections of the corresponding TiDB Server: + Executing the following SQL statement can make the above operation take effect immediately. The effective range includes all old connections of the corresponding TiDB server: {{< copyable "sql" >}} @@ -55,14 +55,19 @@ You can use the blocklist of optimization rules to disable some of them if some > **Note:** > - > `admin reload opt_rule_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. + > `admin reload opt_rule_blacklist` only takes effect on the TiDB server where the above statement has been run. If you want all TiDB servers of the cluster to take effect, run this command on each TiDB server. -- If you want to re-enable some rules, delete the corresponding data in the table, and then run `admin reload` statement: +- If you want to re-enable a rule, delete the corresponding data in the table, and then run the `admin reload` statement: {{< copyable "sql" >}} ```sql delete from mysql.opt_rule_blacklist where name in ("join_reoder", "topn_push_down"); + ``` + + {{< copyable "sql" >}} + + ```sql admin reload opt_rule_blacklist; ``` @@ -74,18 +79,18 @@ The blocklist of expression pushdown is one way to tune the expression pushdown, | Expression Classification | Concrete Operations | | :-------------- | :------------------------------------- | -| [Logical Operations](/functions-and-operators/operators.md#logical-operators) | AND (&&), OR (||), NOT (!) | +| [Logical operations](/functions-and-operators/operators.md#logical-operators) | AND (&&), OR (||), NOT (!) | | [Comparison functions and operators](/functions-and-operators/operators.md#comparison-functions-and-operators) | <, <=, =, != (`<>`), >, >=, [`<=>`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#operator_equal-to), [`IN()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_in), IS NULL, LIKE, IS TRUE, IS FALSE, [`COALESCE()`](https://dev.mysql.com/doc/refman/5.7/en/comparison-operators.html#function_coalesce) | -| [Numberic functions and operators](/functions-and-operators/numeric-functions-and-operators.md) | +, -, *, /, [`ABS()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_abs), [`CEIL()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceil), [`CEILING()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceiling), [`FLOOR()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_floor) | +| [Numeric functions and operators](/functions-and-operators/numeric-functions-and-operators.md) | +, -, *, /, [`ABS()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_abs), [`CEIL()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceil), [`CEILING()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_ceiling), [`FLOOR()`](https://dev.mysql.com/doc/refman/5.7/en/mathematical-functions.html#function_floor) | | [Control flow functions](/functions-and-operators/control-flow-functions.md) | [`CASE`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#operator_case), [`IF()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_if), [`IFNULL()`](https://dev.mysql.com/doc/refman/5.7/en/control-flow-functions.html#function_ifnull) | -| [JSON functions](/functions-and-operators/json-functions.md) | [JSON_TYPE(json_val)][json_type],
[JSON_EXTRACT(json_doc, path[, path] ...)][json_extract],
[JSON_UNQUOTE(json_val)][json_unquote],
[JSON_OBJECT(key, val[, key, val] ...)][json_object],
[JSON_ARRAY([val[, val] ...])][json_array],
[JSON_MERGE(json_doc, json_doc[, json_doc] ...)][json_merge],
[JSON_SET(json_doc, path, val[, path, val] ...)][json_set],
[JSON_INSERT(json_doc, path, val[, path, val] ...)][json_insert],
[JSON_REPLACE(json_doc, path, val[, path, val] ...)][json_replace],
[JSON_REMOVE(json_doc, path[, path] ...)][json_remove] | +| [JSON functions](/functions-and-operators/json-functions.md) | [JSON_TYPE(json_val)](https://dev.mysql.com/doc/refman/5.7/en/json-attribute-functions.html#function_json-type),
[JSON_EXTRACT(json_doc, path[, path] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-search-functions.html#function_json-extract),
[JSON_UNQUOTE(json_val)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-unquote),
[JSON_OBJECT(key, val[, key, val] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-creation-functions.html#function_json-object),
[JSON_ARRAY([val[, val] ...])](https://dev.mysql.com/doc/refman/5.7/en/json-creation-functions.html#function_json-array),
[JSON_MERGE(json_doc, json_doc[, json_doc] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-merge),
[JSON_SET(json_doc, path, val[, path, val] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-set),
[JSON_INSERT(json_doc, path, val[, path, val] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-insert),
[JSON_REPLACE(json_doc, path, val[, path, val] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-replace),
[JSON_REMOVE(json_doc, path[, path] ...)](https://dev.mysql.com/doc/refman/5.7/en/json-modification-functions.html#function_json-remove) | | [Date and time functions](/functions-and-operators/date-and-time-functions.md) | [`DATE_FORMAT()`](https://dev.mysql.com/doc/refman/5.7/en/date-and-time-functions.html#function_date-format) | ### Disable the pushdown of specific expressions -When you get wrong results due to the expression pushdown, using the blocklist can make a quick recovery for the application. More clearly, you can add some of the supported functions or operators to the table `mysql.expr_pushdown_blacklist` to disable the pushdown of some specific expressions. +When you get wrong results due to the expression pushdown, you can use the blocklist to make a quick recovery for the application. More specifically, you can add some of the supported functions or operators to the `mysql.expr_pushdown_blacklist` table to disable the pushdown of specific expressions. -The schema of `mysql.expr_pushdown_blacklist` is shown as below: +The schema of `mysql.expr_pushdown_blacklist` is shown as follows: {{< copyable "sql" >}} @@ -104,42 +109,44 @@ desc mysql.expr_pushdown_blacklist; 3 rows in set (0.00 sec) ``` -Here is the description of each field: +Here is the description of each field above: -+ `name`: The name of expression that is disabled to be pushed down. -+ `store_type`: To specify the component you don't want the expression to be pushed down. Three components `tidb`, `tikv`, and `tiflash` are available. The `store_type` is case-insensitive. Use the comma to divide each component if more than one component is specified. - - The `store_type` `tidb` decides whether the expression can be executed in other TiDB Server when reading the TiDB memory table. - - The `store_type` `tikv` decides whether the expression can be executed in TiKV Server's Coprocessor component. - - The `store_type` `tiflash` decides whether the expression can be executed in TiFlash Server's Coprocessor component. -+ `reason`: To record the reason why this expression is added to the blocklist. ++ `name`: The name of the function that is disabled to be pushed down. ++ `store_type`: To specify the component that you want to prevent the function from being pushed down to for computing. Available components are `tidb`, `tikv`, and `tiflash`. The `store_type` is case-insensitive. If you need to specify multiple components, use a comma to separate each component. + - When `store_type` is `tidb`, it indicates whether the function can be executed in other TiDB servers while the TiDB memory table is being read. + - When `store_type` is `tikv`, it indicates whether the function can be executed in TiKV server's Coprocessor component. + - When `store_type` is `tiflash`, it indicates whether the function can be executed in TiFlash Server's Coprocessor component. ++ `reason`: To record the reason why this function is added to the blocklist. ### Usage +This section describes how to use the blocklist of expression pushdown. + #### Add to the blocklist -Using the following procedures if you want to add one or more expressions to the blocklist: +To add one or more expressions (functions or operators) to the blocklist, perform the following steps: -1. Insert the corresponding function name or operator name and the set of components you want to disable the pushdown to the table `mysql.expr_pushdown_blacklist`. +1. Insert the corresponding function name or operator name, and the set of components you want to disable the pushdown, to the `mysql.expr_pushdown_blacklist` table. 2. Execute `admin reload expr_pushdown_blacklist`. ### Remove from the blocklist -Using the following procedures if you want to remove one or more expressions from the blocklist: +To remove one or more expressions from the blocklist, perform the following steps: -1. Delete the corresponding function name or operator name and the set of components you want to disable the pushdown from the table `mysql.expr_pushdown_blacklist`. +1. Delete the corresponding function name or operator name, and the set of components you want to disable the pushdown, from the `mysql.expr_pushdown_blacklist` table. 2. Execute `admin reload expr_pushdown_blacklist`. > **Note:** > -> `admin reload expr_pushdown_blacklist` only takes effect on the TiDB Server which runs this statement. If you need all TiDB Server of the cluster to disable some rules, you need to run this command on each of the TiDB Server. +> `admin reload expr_pushdown_blacklist` only takes effect on the TiDB server where this statement is run. If you want all TiDB servers of the cluster to take effect, run this command on each TiDB server. ## Expression blocklist usage example -The following example first adds the operator `<` and `>` to the blocklist then removes the operator `>` from the blocklist. +In the following example, the `<` and `>` operators are added to the blocklist, and then the `>` operator is removed from the blocklist. -Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [SQL Tuning with `EXPLAIN`](/query-execution-plan.md)). +To judge whether the blocklist takes effect, observe the results of `EXPLAIN` (See [Optimize SQL statements using `EXPLAIN`](/query-execution-plan.md#optimize-sql-statements-using-explain)). 1. The predicates `a < 2` and `a > 2` in the `WHERE` clause of the following SQL statement can be pushed down to TiKV. @@ -160,7 +167,7 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ 3 rows in set (0.00 sec) ``` -2. Insert the expression to the table `mysql.expr_pushdown_blacklist` and execute `admin reload expr_pushdown_blacklist`. +2. Insert the expression to the `mysql.expr_pushdown_blacklist` table and execute `admin reload expr_pushdown_blacklist`. {{< copyable "sql" >}} @@ -183,7 +190,7 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ Query OK, 0 rows affected (0.00 sec) ``` -3. Observe the execution plan again and you will find that both the operator `<` and `>` are not pushed down to TiKV Coprocessor. +3. Observe the execution plan again and you will find that both the `<` and `>` operators are not pushed down to TiKV Coprocessor. {{< copyable "sql" >}} @@ -202,7 +209,7 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ 3 rows in set (0.00 sec) ``` -4. Remove one expression(here is `>`) from the blocklist and execute `admin reload expr_pushdown_blacklist`. +4. Remove one expression (here is `>`) from the blocklist and execute `admin reload expr_pushdown_blacklist`. {{< copyable "sql" >}} @@ -222,8 +229,9 @@ Whether the blocklist takes effect can be observed in the `EXPLAIN` result(See [ ```sql Query OK, 0 rows affected (0.00 sec) + ``` -5. Observe the execution plan again and you will find that `<` is not pushed down while `>` is not pushed down to TiKV Coprocessor. +5. Observe the execution plan again and you will find that the `<` and `>` operators can be re-pushed down to TiKV Coprocessor again. {{< copyable "sql" >}} From 17d84b921bcd01a36eb1757afe7aca32f85f3626 Mon Sep 17 00:00:00 2001 From: Lilian Lee Date: Wed, 15 Jul 2020 10:13:16 +0800 Subject: [PATCH 7/8] Update blocklist-control-plan.md --- blocklist-control-plan.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/blocklist-control-plan.md b/blocklist-control-plan.md index 277c80c2db99c..97fd9cf0d8f3e 100644 --- a/blocklist-control-plan.md +++ b/blocklist-control-plan.md @@ -62,7 +62,7 @@ You can use the blocklist of optimization rules to disable some of them if some {{< copyable "sql" >}} ```sql - delete from mysql.opt_rule_blacklist where name in ("join_reoder", "topn_push_down"); + delete from mysql.opt_rule_blacklist where name in ("join_reorder", "topn_push_down"); ``` {{< copyable "sql" >}} From 7a9733551d474f6b21aafc080f55598f4bf3ff01 Mon Sep 17 00:00:00 2001 From: Lilian Lee Date: Wed, 15 Jul 2020 10:18:32 +0800 Subject: [PATCH 8/8] Fix description brought by zh version --- blocklist-control-plan.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/blocklist-control-plan.md b/blocklist-control-plan.md index 97fd9cf0d8f3e..27b1c6507c5b7 100644 --- a/blocklist-control-plan.md +++ b/blocklist-control-plan.md @@ -231,7 +231,7 @@ To judge whether the blocklist takes effect, observe the results of `EXPLAIN` (S Query OK, 0 rows affected (0.00 sec) ``` -5. Observe the execution plan again and you will find that the `<` and `>` operators can be re-pushed down to TiKV Coprocessor again. +5. Observe the execution plan again and you will find that `<` is not pushed down while `>` is pushed down to TiKV Coprocessor. {{< copyable "sql" >}}