- Docs Home
- About TiDB Cloud
- Get Started
- Develop Applications
- Overview
- Quick Start
- Build a TiDB Developer Cluster
- CRUD SQL in TiDB
- Build a Simple CRUD App with TiDB
- Example Applications
- Connect to TiDB
- Design Database Schema
- Write Data
- Read Data
- Transaction
- Optimize
- Troubleshoot
- Reference
- Cloud Native Development Environment
- Manage Cluster
- Plan Your Cluster
- Create a TiDB Cluster
- Connect to Your TiDB Cluster
- Set Up VPC Peering Connections
- Use an HTAP Cluster with TiFlash
- Scale a TiDB Cluster
- Upgrade a TiDB Cluster
- Delete a TiDB Cluster
- Use TiDB Cloud API (Beta)
- Migrate Data
- Import Sample Data
- Migrate Data into TiDB
- Configure Amazon S3 Access and GCS Access
- Migrate from MySQL-Compatible Databases
- Migrate Incremental Data from MySQL-Compatible Databases
- Migrate from Amazon Aurora MySQL in Bulk
- Import or Migrate from Amazon S3 or GCS to TiDB Cloud
- Import CSV Files from Amazon S3 or GCS into TiDB Cloud
- Import Apache Parquet Files from Amazon S3 or GCS into TiDB Cloud
- Troubleshoot Access Denied Errors during Data Import from Amazon S3
- Export Data from TiDB
- Back Up and Restore
- Monitor and Alert
- Overview
- Built-in Monitoring
- Built-in Alerting
- Third-Party Monitoring Integrations
- Tune Performance
- Overview
- Analyze Performance
- SQL Tuning
- Overview
- Understanding the Query Execution Plan
- SQL Optimization Process
- Overview
- Logic Optimization
- Physical Optimization
- Prepare Execution Plan Cache
- Control Execution Plans
- TiKV Follower Read
- Coprocessor Cache
- Garbage Collection (GC)
- Tune TiFlash performance
- Manage User Access
- Billing
- Reference
- TiDB Cluster Architecture
- TiDB Cloud Cluster Limits and Quotas
- TiDB Limitations
- SQL
- Explore SQL with TiDB
- SQL Language Structure and Syntax
- SQL Statements
ADD COLUMN
ADD INDEX
ADMIN
ADMIN CANCEL DDL
ADMIN CHECKSUM TABLE
ADMIN CHECK [TABLE|INDEX]
ADMIN SHOW DDL [JOBS|QUERIES]
ALTER DATABASE
ALTER INDEX
ALTER TABLE
ALTER TABLE COMPACT
ALTER USER
ANALYZE TABLE
BATCH
BEGIN
CHANGE COLUMN
COMMIT
CHANGE DRAINER
CHANGE PUMP
CREATE [GLOBAL|SESSION] BINDING
CREATE DATABASE
CREATE INDEX
CREATE ROLE
CREATE SEQUENCE
CREATE TABLE LIKE
CREATE TABLE
CREATE USER
CREATE VIEW
DEALLOCATE
DELETE
DESC
DESCRIBE
DO
DROP [GLOBAL|SESSION] BINDING
DROP COLUMN
DROP DATABASE
DROP INDEX
DROP ROLE
DROP SEQUENCE
DROP STATS
DROP TABLE
DROP USER
DROP VIEW
EXECUTE
EXPLAIN ANALYZE
EXPLAIN
FLASHBACK TABLE
FLUSH PRIVILEGES
FLUSH STATUS
FLUSH TABLES
GRANT <privileges>
GRANT <role>
INSERT
KILL [TIDB]
MODIFY COLUMN
PREPARE
RECOVER TABLE
RENAME INDEX
RENAME TABLE
REPLACE
REVOKE <privileges>
REVOKE <role>
ROLLBACK
SELECT
SET DEFAULT ROLE
SET [NAMES|CHARACTER SET]
SET PASSWORD
SET ROLE
SET TRANSACTION
SET [GLOBAL|SESSION] <variable>
SHOW ANALYZE STATUS
SHOW [GLOBAL|SESSION] BINDINGS
SHOW BUILTINS
SHOW CHARACTER SET
SHOW COLLATION
SHOW [FULL] COLUMNS FROM
SHOW CREATE SEQUENCE
SHOW CREATE TABLE
SHOW CREATE USER
SHOW DATABASES
SHOW DRAINER STATUS
SHOW ENGINES
SHOW ERRORS
SHOW [FULL] FIELDS FROM
SHOW GRANTS
SHOW INDEX [FROM|IN]
SHOW INDEXES [FROM|IN]
SHOW KEYS [FROM|IN]
SHOW MASTER STATUS
SHOW PLUGINS
SHOW PRIVILEGES
SHOW [FULL] PROCESSSLIST
SHOW PROFILES
SHOW PUMP STATUS
SHOW SCHEMAS
SHOW STATS_HEALTHY
SHOW STATS_HISTOGRAMS
SHOW STATS_META
SHOW STATUS
SHOW TABLE NEXT_ROW_ID
SHOW TABLE REGIONS
SHOW TABLE STATUS
SHOW [FULL] TABLES
SHOW [GLOBAL|SESSION] VARIABLES
SHOW WARNINGS
SHUTDOWN
SPLIT REGION
START TRANSACTION
TABLE
TRACE
TRUNCATE
UPDATE
USE
WITH
- Data Types
- Functions and Operators
- Overview
- Type Conversion in Expression Evaluation
- Operators
- Control Flow Functions
- String Functions
- Numeric Functions and Operators
- Date and Time Functions
- Bit Functions and Operators
- Cast Functions and Operators
- Encryption and Compression Functions
- Locking Functions
- Information Functions
- JSON Functions
- Aggregate (GROUP BY) Functions
- Window Functions
- Miscellaneous Functions
- Precision Math
- Set Operations
- List of Expressions for Pushdown
- TiDB Specific Functions
- Clustered Indexes
- Constraints
- Generated Columns
- SQL Mode
- Table Attributes
- Transactions
- Views
- Partitioning
- Temporary Tables
- Cached Tables
- Character Set and Collation
- Read Historical Data
- System Tables
mysql
- INFORMATION_SCHEMA
- Overview
ANALYZE_STATUS
CLIENT_ERRORS_SUMMARY_BY_HOST
CLIENT_ERRORS_SUMMARY_BY_USER
CLIENT_ERRORS_SUMMARY_GLOBAL
CHARACTER_SETS
CLUSTER_INFO
COLLATIONS
COLLATION_CHARACTER_SET_APPLICABILITY
COLUMNS
DATA_LOCK_WAITS
DDL_JOBS
DEADLOCKS
ENGINES
KEY_COLUMN_USAGE
PARTITIONS
PROCESSLIST
REFERENTIAL_CONSTRAINTS
SCHEMATA
SEQUENCES
SESSION_VARIABLES
SLOW_QUERY
STATISTICS
TABLES
TABLE_CONSTRAINTS
TABLE_STORAGE_STATS
TIDB_HOT_REGIONS_HISTORY
TIDB_INDEXES
TIDB_SERVERS_INFO
TIDB_TRX
TIFLASH_REPLICA
TIKV_REGION_PEERS
TIKV_REGION_STATUS
TIKV_STORE_STATUS
USER_PRIVILEGES
VIEWS
- System Variables
- API Reference
- Storage Engines
- Dumpling
- Table Filter
- Troubleshoot Inconsistency Between Data and Indexes
- FAQs
- Release Notes
- Support
- Glossary
SQL Prepare Execution Plan Cache
TiDB supports execution plan caching for Prepare
and Execute
queries. This includes both forms of prepared statements:
- Using the
COM_STMT_PREPARE
andCOM_STMT_EXECUTE
protocol features. - Using the SQL statements
PREPARE
andEXECUTE
.
The TiDB optimizer handles these two types of queries in the same way: when preparing, the parameterized query is parsed into an AST (Abstract Syntax Tree) and cached; in later execution, the execution plan is generated based on the stored AST and specific parameter values.
When the execution plan cache is enabled, in the first execution every Prepare
statement checks whether the current query can use the execution plan cache, and if the query can use it, then put the generated execution plan into a cache implemented by LRU (Least Recently Used) linked list. In the subsequent Execute
queries, the execution plan is obtained from the cache and checked for availability. If the check succeeds, the step of generating an execution plan is skipped. Otherwise, the execution plan is regenerated and saved in the cache.
In the current version of TiDB, if a Prepare
statement meets any of the following conditions, the query or the plan is not cached:
- The query contains SQL statements other than
SELECT
,UPDATE
,INSERT
,DELETE
,Union
,Intersect
, andExcept
. - The query accesses partitioned tables or temporary tables, or a table that contains generated columns.
- The query contains sub-queries, such as
select * from t where a > (select ...)
. - The query contains the
ignore_plan_cache
hint, such asselect /*+ ignore_plan_cache() */ * from t
. - The query contains variables other than
?
(including system variables or user-defined variables), such asselect * from t where a>? and b>@x
. - The query contains the functions that cannot be cached:
database()
,current_user
,current_role
,user
,connection_id
,last_insert_id
,row_count
,version
, andlike
. - The query contains
?
afterLimit
, such asLimit ?
andLimit 10, ?
. Such queries are not cached because the specific value of?
has a great impact on query performance. - The query contains
?
afterOrder By
, such asOrder By ?
. Such queries sort data based on the column specified by?
. If the queries targeting different columns use the same execution plan, the results will be wrong. Therefore, such queries are not cached. However, if the query is a common one, such asOrder By a+?
, it is cached. - The query contains
?
afterGroup By
, such asGroup By?
. Such queries group data based on the column specified by?
. If the queries targeting different columns use the same execution plan, the results will be wrong. Therefore, such queries are not cached. However, if the query is a common one, such asGroup By a+?
, it is cached. - The query contains
?
in the definition of theWindow Frame
window function, such as(partition by year order by sale rows ? preceding)
. If?
appears elsewhere in the window function, the query is cached. - The query contains parameters for comparing
int
andstring
, such asc_int >= ?
orc_int in (?, ?)
, in which?
indicates the string type, such asset @x='123'
. To ensure that the query result is compatible with MySQL, parameters need to be adjusted in each query, so such queries are not cached. - The plan attempts to access
TiFlash
. - In most cases, the plan that contains
TableDual
is not cached, unless the currentPrepare
statement does not have parameters.
The LRU linked list is designed as a session-level cache because Prepare
/ Execute
cannot be executed across sessions. Each element of the LRU list is a key-value pair. The value is the execution plan, and the key is composed of the following parts:
- The name of the database where
Execute
is executed - The identifier of the
Prepare
statement, that is, the name after thePREPARE
keyword - The current schema version, which is updated after every successfully executed DDL statement
- The SQL mode when executing
Execute
- The current time zone, which is the value of the
time_zone
system variable - The value of the
sql_select_limit
system variable
Any change in the above information (for example, switching databases, renaming Prepare
statement, executing DDL statements, or modifying the value of SQL mode / time_zone
), or the LRU cache elimination mechanism causes the execution plan cache miss when executing.
After the execution plan cache is obtained from the cache, TiDB first checks whether the execution plan is still valid. If the current Execute
statement is executed in an explicit transaction, and the referenced table is modified in the transaction pre-order statement, the cached execution plan accessing this table does not contain the UnionScan
operator, then it cannot be executed.
After the validation test is passed, the scan range of the execution plan is adjusted according to the current parameter values, and then used to perform data querying.
There are several points worth noting about execution plan caching and query performance:
- No matter an execution plan is cached or not, it is affected by SQL bindings. For execution plans that have not been cached (the first
Execute
), these plans are affected by existing SQL bindings. For execution plans that have been cached, if new SQL Bindings are created, these plans become invalid. - Cached plans are not affected by changes in statistics, optimization rules, and blocklist pushdown by expressions.
- Considering that the parameters of
Execute
are different, the execution plan cache prohibits some aggressive query optimization methods that are closely related to specific parameter values to ensure adaptability. This causes that the query plan may not be optimal for certain parameter values. For example, the filter condition of the query iswhere a > ? And a < ?
, the parameters of the firstExecute
statement are2
and1
respectively. Considering that these two parameters maybe be1
and2
in the next execution time, the optimizer does not generate the optimalTableDual
execution plan that is specific to current parameter values; - If cache invalidation and elimination are not considered, an execution plan cache is applied to various parameter values, which in theory also results in non-optimal execution plans for certain values. For example, if the filter condition is
where a < ?
and the parameter value used for the first execution is1
, then the optimizer generates the optimalIndexScan
execution plan and puts it into the cache. In the subsequent executions, if the value becomes10000
, theTableScan
plan might be the better one. But due to the execution plan cache, the previously generatedIndexScan
is used for execution. Therefore, the execution plan cache is more suitable for application scenarios where the query is simple (the ratio of compilation is high) and the execution plan is relatively fixed.
Since v6.1.0, the execution plan cache is enabled by default. You can control prepared plan cache via the system variable tidb_enable_prepared_plan_cache
.
The execution plan cache feature applies only to Prepare
/ Execute
queries and does not take effect for normal queries.
After the execution plan cache feature is enabled, you can use the session-level system variable last_plan_from_cache
to see whether the previous Execute
statement used the cached execution plan, for example:
MySQL [test]> create table t(a int);
Query OK, 0 rows affected (0.00 sec)
MySQL [test]> prepare stmt from 'select * from t where a = ?';
Query OK, 0 rows affected (0.00 sec)
MySQL [test]> set @a = 1;
Query OK, 0 rows affected (0.00 sec)
-- The first execution generates an execution plan and saves it in the cache.
MySQL [test]> execute stmt using @a;
Empty set (0.00 sec)
MySQL [test]> select @@last_plan_from_cache;
+------------------------+
| @@last_plan_from_cache |
+------------------------+
| 0 |
+------------------------+
1 row in set (0.00 sec)
-- The second execution hits the cache.
MySQL [test]> execute stmt using @a;
Empty set (0.00 sec)
MySQL [test]> select @@last_plan_from_cache;
+------------------------+
| @@last_plan_from_cache |
+------------------------+
| 1 |
+------------------------+
1 row in set (0.00 sec)
If you find that a certain set of Prepare
/ Execute
has unexpected behavior due to the execution plan cache, you can use the ignore_plan_cache()
SQL hint to skip using the execution plan cache for the current statement. Still, use the above statement as an example:
MySQL [test]> prepare stmt from 'select /*+ ignore_plan_cache() */ * from t where a = ?';
Query OK, 0 rows affected (0.00 sec)
MySQL [test]> set @a = 1;
Query OK, 0 rows affected (0.00 sec)
MySQL [test]> execute stmt using @a;
Empty set (0.00 sec)
MySQL [test]> select @@last_plan_from_cache;
+------------------------+
| @@last_plan_from_cache |
+------------------------+
| 0 |
+------------------------+
1 row in set (0.00 sec)
MySQL [test]> execute stmt using @a;
Empty set (0.00 sec)
MySQL [test]> select @@last_plan_from_cache;
+------------------------+
| @@last_plan_from_cache |
+------------------------+
| 0 |
+------------------------+
1 row in set (0.00 sec)
Memory management of Prepared Plan Cache
Using Prepared Plan Cache has some memory overhead. In internal tests, each cached plan consumes an average of 100 KiB of memory. Because Plan Cache is currently at the SESSION
level, the total memory consumption is approximately the number of sessions * the average number of cached plans in a session * 100 KiB
.
For example, the current TiDB instance has 50 sessions in concurrency and each session has approximately 100 cached plans. The total memory consumption is approximately 50 * 100 * 100 KiB
= 512 MB
.
You can control the maximum number of plans that can be cached in each session by configuring the system variable tidb_prepared_plan_cache_size
. For different environments, the recommended value is as follows:
- When the memory threshold of the TiDB server instance is <= 64 GiB, set
tidb_prepared_plan_cache_size
to50
. - When the memory threshold of the TiDB server instance is > 64 GiB, set
tidb_prepared_plan_cache_size
to100
.
When the unused memory of the TiDB server is less than a certain threshold, the memory protection mechanism of plan cache is triggered, through which some cached plans will be evicted.
You can control the threshold by configuring the system variable tidb_prepared_plan_cache_memory_guard_ratio
. The threshold is 0.1 by default, which means when the unused memory of the TiDB server is less than 10% of the total memory (90% of the memory is used), the memory protection mechanism is triggered.
Due to memory limit, plan cache might be missed sometimes. You can check the status by viewing the Plan Cache Miss OPS
metric in the Grafana dashboard.
Due to memory limit, plan cache might be missed sometimes.
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:
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:
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
:
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:
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
to ON
so TiDB ignores commands to close prepare stmt
:
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)