diff --git a/sql-prepare-plan-cache.md b/sql-prepare-plan-cache.md index 1492325accc5c..ee454bc52abc1 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) ``` + +## Clear execution plan cache + +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. + +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 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" >}} + +```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 '...'; -- Prepare once +MySQL [test]> execute stmt using ...; +MySQL [test]> deallocate prepare stmt; -- Release the prepared statement +MySQL [test]> prepare stmt from '...'; -- Prepare twice +MySQL [test]> execute stmt using ...; +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-v600) to `ON` so 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'; -- Prepare once +Query OK, 0 rows affected (0.00 sec) + +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'; -- Prepare twice +Query OK, 0 rows affected (0.00 sec) + +mysql> execute stmt; -- Execute twice +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..0272b17d23595 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. 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 - Scope: SESSION | GLOBAL