From 4265636b080285328ff083e16d35171930b2cbdd Mon Sep 17 00:00:00 2001 From: shichun-0415 Date: Sun, 27 Mar 2022 23:05:05 +0800 Subject: [PATCH 1/9] update documents related to Plan Cache --- sql-prepare-plan-cache.md | 116 ++++++++++++++++++++++++++++++++++++++ system-variables.md | 7 +++ 2 files changed, 123 insertions(+) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index 1492325accc5c..47783e26bb46c 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -119,3 +119,119 @@ MySQL [test]> select @@last_plan_from_cache; +------------------------+ 1 row in set (0.00 sec) ``` + +## Manually clear execution plan cache + +You can manually clear execution plan cache by executing the `ADMIN FLUSH [SESSION | INSTANCE] PLAN_CACHE` statement. + +In this statement, `[SESSION | INSTANCE]`specifies whether the plan cache is cleared for the current session or the whole TiDB instance. If the scope is left blank, the statement above applies to `SESSION` cache by default. + +The following is an example of clearing the `SESSION` execution plan cache: + +{{< copyable "sql" >}} + +```sql +MySQL [test]> create table t (a int); +Query OK, 0 rows affected (0.00 sec) + +MySQL [test]> prepare stmt from 'select * from t'; +Query OK, 0 rows affected (0.00 sec) + +MySQL [test]> execute stmt; +Empty set (0.00 sec) + +MySQL [test]> execute stmt; +Empty set (0.00 sec) + +MySQL [test]> select @@last_plan_from_cache; -- Select the cached plan ++------------------------+ +| @@last_plan_from_cache | ++------------------------+ +| 1 | ++------------------------+ +1 row in set (0.00 sec) + +MySQL [test]> admin flush session plan_cache; -- Clear the cached plan of the current session +Query OK, 0 rows affected (0.00 sec) + +MySQL [test]> execute stmt; +Empty set (0.00 sec) + +MySQL [test]> select @@last_plan_from_cache; -- The cached plan cannot be selected again, because it has been cleared ++------------------------+ +| @@last_plan_from_cache | ++------------------------+ +| 0 | ++------------------------+ +1 row in set (0.00 sec) +``` + +Currently, TiDB does not support clearing `GLOBAL` execution plan cache. That means you cannot clear the cached plan of the whole TiDB cluster. The following error is reported if you try to clear the `GLOBAL` execution plan cache: + +{{< copyable "sql" >}} + +```sql +MySQL [test]> admin flush global plan_cache; +ERROR 1105 (HY000): Do not support the 'admin flush global scope.' +``` + +## Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement + +To reduce syntax analysis for executed SQL statements, it is recommended that you run `prepare stmt` once, then `execute stmt` multiple times before running `deallocate prepare`: + +{{< copyable "sql" >}} + +```sql +MySQL [test]> prepare stmt from '...'; -- prepare once +MySQL [test]> execute stmt using ...; -- execute once +MySQL [test]> ... +MySQL [test]> execute stmt using ...; -- execute multiple times +MySQL [test]> deallocate prepare stmt; -- Release the prepared statement +``` + +In real practice, you may be used to running `deallocate prepare` each time after running `execute stmt`, as shown below: + +{{< copyable "sql" >}} + +```sql +MySQL [test]> prepare stmt from '...'; -- First prepare +MySQL [test]> execute stmt using ...; +MySQL [test]> deallocate prepare stmt; -- Release the prepared statement +MySQL [test]> prepare stmt from '...'; -- Second prepare +MySQL [test]> execute stmt using ...; +MySQL [test]> deallocate prepare stmt; -- Release the prepared statement +``` + +In such practice, the plan obtained by the first execute statement cannot be reused by the second execute statement. + +To address the problem, you can use the system varible [`tidb_ignore_prepared_cache_close_stmt`](/system-variables.md#tidb_ignore_prepared_cache_close_stmt-new-in v60). After this variable is set to `ON`, TiDB ignores commands to close `prepare stmt`: + +{{< copyable "sql" >}} + +```sql +mysql> set @@tidb_ignore_prepared_cache_close_stmt=1; -- Enable the variable +Query OK, 0 rows affected (0.00 sec) + +mysql> prepare stmt from 'select * from t'; -- First prepare +Query OK, 0 rows affected (0.00 sec) + +mysql> execute stmt; -- First execute +Empty set (0.00 sec) + +mysql> deallocate prepare stmt; -- Release after the first execute +Query OK, 0 rows affected (0.00 sec) + +mysql> prepare stmt from 'select * from t'; -- Second prepare +Query OK, 0 rows affected (0.00 sec) + +mysql> execute stmt; -- Second execute +Empty set (0.00 sec) + +mysql> select @@last_plan_from_cache; -- Reuse the last plan ++------------------------+ +| @@last_plan_from_cache | ++------------------------+ +| 1 | ++------------------------+ +1 row in set (0.00 sec) +``` \ No newline at end of file diff --git a/system-variables.md b/system-variables.md index bb19b7a353731..fd8caf7fa3aaa 100644 --- a/system-variables.md +++ b/system-variables.md @@ -1116,6 +1116,13 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - When the parameter of the aggregate function is not distinct, `HashAgg` is run concurrently and respectively in two phases - the `partial` phase and the `final` phase. - A value of `-1` means that the value of `tidb_executor_concurrency` will be used instead. +### tidb_ignore_prepared_cache_close_stmt ((New in v6.0.0)) + +- Scope: SESSION | GLOBAL +- Default value: `OFF` +- This variable is used to set whether to ignore the commands for closing prepared statement cache. +- When this variable is set to `ON`, the `COM_STMT_CLOSE` command of the Binary protocol and the [`DEALLOCATE PREPARE`](/sql-statements/sql-statement-deallocate.md) statement of the text protocol are ignored. + ### tidb_index_join_batch_size - Scope: SESSION | GLOBAL From 0c27f01f69905c9031ef738afa4ec0591df9d5b5 Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Mon, 28 Mar 2022 11:21:04 +0800 Subject: [PATCH 2/9] fix format --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index fd8caf7fa3aaa..8492cd79186cd 100644 --- a/system-variables.md +++ b/system-variables.md @@ -1116,7 +1116,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - When the parameter of the aggregate function is not distinct, `HashAgg` is run concurrently and respectively in two phases - the `partial` phase and the `final` phase. - A value of `-1` means that the value of `tidb_executor_concurrency` will be used instead. -### tidb_ignore_prepared_cache_close_stmt ((New in v6.0.0)) +### tidb_ignore_prepared_cache_close_stmt (New in v6.0.0) - Scope: SESSION | GLOBAL - Default value: `OFF` From 4a1bab9c7019100ce9180da23225132ea2384824 Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Tue, 29 Mar 2022 16:17:55 +0800 Subject: [PATCH 3/9] address comment --- sql-prepare-plan-cache.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index 47783e26bb46c..10a59b1c69c82 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -177,7 +177,7 @@ ERROR 1105 (HY000): Do not support the 'admin flush global scope.' ## Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement -To reduce syntax analysis for executed SQL statements, it is recommended that you run `prepare stmt` once, then `execute stmt` multiple times before running `deallocate prepare`: +To reduce optimization cost for executed SQL statements, it is recommended that you run `prepare stmt` once, then `execute stmt` multiple times before running `deallocate prepare`: {{< copyable "sql" >}} From ad6d936940844a28e89defaedc43762834e16022 Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Thu, 31 Mar 2022 22:20:03 +0800 Subject: [PATCH 4/9] Apply suggestions from code review Co-authored-by: Grace Cai --- sql-prepare-plan-cache.md | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index 10a59b1c69c82..bb2f91b4a2f6b 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -124,7 +124,7 @@ MySQL [test]> select @@last_plan_from_cache; You can manually clear execution plan cache by executing the `ADMIN FLUSH [SESSION | INSTANCE] PLAN_CACHE` statement. -In this statement, `[SESSION | INSTANCE]`specifies whether the plan cache is cleared for the current session or the whole TiDB instance. If the scope is left blank, the statement above applies to `SESSION` cache by default. +In this statement, `[SESSION | INSTANCE]`specifies whether the plan cache is cleared for the current session or the whole TiDB instance. If the scope is not specified, the statement above applies to the `SESSION` cache by default. The following is an example of clearing the `SESSION` execution plan cache: @@ -177,7 +177,7 @@ ERROR 1105 (HY000): Do not support the 'admin flush global scope.' ## Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement -To reduce optimization cost for executed SQL statements, it is recommended that you run `prepare stmt` once, then `execute stmt` multiple times before running `deallocate prepare`: +To reduce the syntax parsing cost of SQL statements, it is recommended that you run `prepare stmt` once, then `execute stmt` multiple times before running `deallocate prepare`: {{< copyable "sql" >}} @@ -202,9 +202,9 @@ MySQL [test]> execute stmt using ...; MySQL [test]> deallocate prepare stmt; -- Release the prepared statement ``` -In such practice, the plan obtained by the first execute statement cannot be reused by the second execute statement. +In such practice, the plan obtained by the first executed statement cannot be reused by the second executed statement. -To address the problem, you can use the system varible [`tidb_ignore_prepared_cache_close_stmt`](/system-variables.md#tidb_ignore_prepared_cache_close_stmt-new-in v60). After this variable is set to `ON`, TiDB ignores commands to close `prepare stmt`: +To address the problem, you can set the system varible [`tidb_ignore_prepared_cache_close_stmt`](/system-variables.md#tidb_ignore_prepared_cache_close_stmt-new-in v60) to `ON` so TiDB ignores commands to close `prepare stmt`: {{< copyable "sql" >}} From 5d69d8c2c52dcf967276e8d9ed60d637466f9ba7 Mon Sep 17 00:00:00 2001 From: shichun-0415 Date: Thu, 31 Mar 2022 22:32:06 +0800 Subject: [PATCH 5/9] Fix style --- sql-prepare-plan-cache.md | 18 +++++++++--------- 1 file changed, 9 insertions(+), 9 deletions(-) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index bb2f91b4a2f6b..9b793fd5b6e0c 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -182,10 +182,10 @@ To reduce the syntax parsing cost of SQL statements, it is recommended that you {{< copyable "sql" >}} ```sql -MySQL [test]> prepare stmt from '...'; -- prepare once -MySQL [test]> execute stmt using ...; -- execute once +MySQL [test]> prepare stmt from '...'; -- Prepare once +MySQL [test]> execute stmt using ...; -- Execute once MySQL [test]> ... -MySQL [test]> execute stmt using ...; -- execute multiple times +MySQL [test]> execute stmt using ...; -- Execute multiple times MySQL [test]> deallocate prepare stmt; -- Release the prepared statement ``` @@ -194,10 +194,10 @@ In real practice, you may be used to running `deallocate prepare` each time afte {{< copyable "sql" >}} ```sql -MySQL [test]> prepare stmt from '...'; -- First prepare +MySQL [test]> prepare stmt from '...'; -- Prepare once MySQL [test]> execute stmt using ...; MySQL [test]> deallocate prepare stmt; -- Release the prepared statement -MySQL [test]> prepare stmt from '...'; -- Second prepare +MySQL [test]> prepare stmt from '...'; -- Prepare twice MySQL [test]> execute stmt using ...; MySQL [test]> deallocate prepare stmt; -- Release the prepared statement ``` @@ -212,19 +212,19 @@ To address the problem, you can set the system varible [`tidb_ignore_prepared_ca mysql> set @@tidb_ignore_prepared_cache_close_stmt=1; -- Enable the variable Query OK, 0 rows affected (0.00 sec) -mysql> prepare stmt from 'select * from t'; -- First prepare +mysql> prepare stmt from 'select * from t'; -- Prepare once Query OK, 0 rows affected (0.00 sec) -mysql> execute stmt; -- First execute +mysql> execute stmt; -- Execute once Empty set (0.00 sec) mysql> deallocate prepare stmt; -- Release after the first execute Query OK, 0 rows affected (0.00 sec) -mysql> prepare stmt from 'select * from t'; -- Second prepare +mysql> prepare stmt from 'select * from t'; -- Prepare twice Query OK, 0 rows affected (0.00 sec) -mysql> execute stmt; -- Second execute +mysql> execute stmt; -- Execute twice Empty set (0.00 sec) mysql> select @@last_plan_from_cache; -- Reuse the last plan From ce2065f94f887aff52d4d347ef206966c2e3ef68 Mon Sep 17 00:00:00 2001 From: shichun-0415 Date: Fri, 1 Apr 2022 17:08:01 +0800 Subject: [PATCH 6/9] Remove manually --- sql-prepare-plan-cache.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index 9b793fd5b6e0c..dff1f490a3e42 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -120,9 +120,9 @@ MySQL [test]> select @@last_plan_from_cache; 1 row in set (0.00 sec) ``` -## Manually clear execution plan cache +## Clear execution plan cache -You can manually clear execution plan cache by executing the `ADMIN FLUSH [SESSION | INSTANCE] PLAN_CACHE` statement. +You can clear execution plan cache by executing the `ADMIN FLUSH [SESSION | INSTANCE] PLAN_CACHE` statement. In this statement, `[SESSION | INSTANCE]`specifies whether the plan cache is cleared for the current session or the whole TiDB instance. If the scope is not specified, the statement above applies to the `SESSION` cache by default. From de80bd3948d930184550aed174d0959fe74d41e1 Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Fri, 1 Apr 2022 17:10:32 +0800 Subject: [PATCH 7/9] Update system-variables.md --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index 8492cd79186cd..d72dfbbf79742 100644 --- a/system-variables.md +++ b/system-variables.md @@ -1121,7 +1121,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - Scope: SESSION | GLOBAL - Default value: `OFF` - This variable is used to set whether to ignore the commands for closing prepared statement cache. -- When this variable is set to `ON`, the `COM_STMT_CLOSE` command of the Binary protocol and the [`DEALLOCATE PREPARE`](/sql-statements/sql-statement-deallocate.md) statement of the text protocol are ignored. +- When this variable is set to `ON`, the `COM_STMT_CLOSE` command of the Binary protocol and the [`DEALLOCATE PREPARE`](/sql-statements/sql-statement-deallocate.md) statement of the text protocol are ignored. For details, see [Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement](sql-prepare-plan-cache.md#ignore-the-com_stmt_close-command-and-the-deallocate-prepare-statement). ### tidb_index_join_batch_size From 874a364a33078226c48459f417202acbd4f3265c Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Fri, 1 Apr 2022 17:31:17 +0800 Subject: [PATCH 8/9] fix CI --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index d72dfbbf79742..0272b17d23595 100644 --- a/system-variables.md +++ b/system-variables.md @@ -1121,7 +1121,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - Scope: SESSION | GLOBAL - Default value: `OFF` - This variable is used to set whether to ignore the commands for closing prepared statement cache. -- When this variable is set to `ON`, the `COM_STMT_CLOSE` command of the Binary protocol and the [`DEALLOCATE PREPARE`](/sql-statements/sql-statement-deallocate.md) statement of the text protocol are ignored. For details, see [Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement](sql-prepare-plan-cache.md#ignore-the-com_stmt_close-command-and-the-deallocate-prepare-statement). +- When this variable is set to `ON`, the `COM_STMT_CLOSE` command of the Binary protocol and the [`DEALLOCATE PREPARE`](/sql-statements/sql-statement-deallocate.md) statement of the text protocol are ignored. For details, see [Ignore the `COM_STMT_CLOSE` command and the `DEALLOCATE PREPARE` statement](/sql-prepare-plan-cache.md#ignore-the-com_stmt_close-command-and-the-deallocate-prepare-statement). ### tidb_index_join_batch_size From f18bd09ee91613f0e00572a1d3cdf283a78b61bb Mon Sep 17 00:00:00 2001 From: shichun-0415 <89768198+shichun-0415@users.noreply.github.com> Date: Fri, 1 Apr 2022 19:38:27 +0800 Subject: [PATCH 9/9] Update sql-prepare-plan-cache.md Co-authored-by: Grace Cai --- sql-prepare-plan-cache.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index dff1f490a3e42..ee454bc52abc1 100644 --- a/sql-prepare-plan-cache.md +++ b/sql-prepare-plan-cache.md @@ -204,7 +204,7 @@ MySQL [test]> deallocate prepare stmt; -- Release the prepared statement In such practice, the plan obtained by the first executed statement cannot be reused by the second executed statement. -To address the problem, you can set the system varible [`tidb_ignore_prepared_cache_close_stmt`](/system-variables.md#tidb_ignore_prepared_cache_close_stmt-new-in v60) to `ON` so TiDB ignores commands to close `prepare stmt`: +To address the problem, you can set the system varible [`tidb_ignore_prepared_cache_close_stmt`](/system-variables.md#tidb_ignore_prepared_cache_close_stmt-new-in-v600) to `ON` so TiDB ignores commands to close `prepare stmt`: {{< copyable "sql" >}}