- 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 COLUMNADD INDEXADMINADMIN CANCEL DDLADMIN CHECKSUM TABLEADMIN CHECK [TABLE|INDEX]ADMIN SHOW DDL [JOBS|QUERIES]ALTER DATABASEALTER INDEXALTER TABLEALTER TABLE COMPACTALTER USERANALYZE TABLEBATCHBEGINCHANGE COLUMNCOMMITCHANGE DRAINERCHANGE PUMPCREATE [GLOBAL|SESSION] BINDINGCREATE DATABASECREATE INDEXCREATE ROLECREATE SEQUENCECREATE TABLE LIKECREATE TABLECREATE USERCREATE VIEWDEALLOCATEDELETEDESCDESCRIBEDODROP [GLOBAL|SESSION] BINDINGDROP COLUMNDROP DATABASEDROP INDEXDROP ROLEDROP SEQUENCEDROP STATSDROP TABLEDROP USERDROP VIEWEXECUTEEXPLAIN ANALYZEEXPLAINFLASHBACK TABLEFLUSH PRIVILEGESFLUSH STATUSFLUSH TABLESGRANT <privileges>GRANT <role>INSERTKILL [TIDB]MODIFY COLUMNPREPARERECOVER TABLERENAME INDEXRENAME TABLEREPLACEREVOKE <privileges>REVOKE <role>ROLLBACKSELECTSET DEFAULT ROLESET [NAMES|CHARACTER SET]SET PASSWORDSET ROLESET TRANSACTIONSET [GLOBAL|SESSION] <variable>SHOW ANALYZE STATUSSHOW [GLOBAL|SESSION] BINDINGSSHOW BUILTINSSHOW CHARACTER SETSHOW COLLATIONSHOW [FULL] COLUMNS FROMSHOW CREATE SEQUENCESHOW CREATE TABLESHOW CREATE USERSHOW DATABASESSHOW DRAINER STATUSSHOW ENGINESSHOW ERRORSSHOW [FULL] FIELDS FROMSHOW GRANTSSHOW INDEX [FROM|IN]SHOW INDEXES [FROM|IN]SHOW KEYS [FROM|IN]SHOW MASTER STATUSSHOW PLUGINSSHOW PRIVILEGESSHOW [FULL] PROCESSSLISTSHOW PROFILESSHOW PUMP STATUSSHOW SCHEMASSHOW STATS_HEALTHYSHOW STATS_HISTOGRAMSSHOW STATS_METASHOW STATUSSHOW TABLE NEXT_ROW_IDSHOW TABLE REGIONSSHOW TABLE STATUSSHOW [FULL] TABLESSHOW [GLOBAL|SESSION] VARIABLESSHOW WARNINGSSHUTDOWNSPLIT REGIONSTART TRANSACTIONTABLETRACETRUNCATEUPDATEUSEWITH
- 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_STATUSCLIENT_ERRORS_SUMMARY_BY_HOSTCLIENT_ERRORS_SUMMARY_BY_USERCLIENT_ERRORS_SUMMARY_GLOBALCHARACTER_SETSCLUSTER_INFOCOLLATIONSCOLLATION_CHARACTER_SET_APPLICABILITYCOLUMNSDATA_LOCK_WAITSDDL_JOBSDEADLOCKSENGINESKEY_COLUMN_USAGEPARTITIONSPROCESSLISTREFERENTIAL_CONSTRAINTSSCHEMATASEQUENCESSESSION_VARIABLESSLOW_QUERYSTATISTICSTABLESTABLE_CONSTRAINTSTABLE_STORAGE_STATSTIDB_HOT_REGIONS_HISTORYTIDB_INDEXESTIDB_SERVERS_INFOTIDB_TRXTIFLASH_REPLICATIKV_REGION_PEERSTIKV_REGION_STATUSTIKV_STORE_STATUSUSER_PRIVILEGESVIEWS
- System Variables
- API Reference
- Storage Engines
- Dumpling
- Table Filter
- Troubleshoot Inconsistency Between Data and Indexes
- FAQs
- Release Notes
- Support
- Glossary
TIDB_TRX
The TIDB_TRX table provides information about the transactions currently being executed on the TiDB node.
USE information_schema;
DESC tidb_trx;
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+
| ID | bigint(21) unsigned | NO | PRI | NULL | |
| START_TIME | timestamp(6) | YES | | NULL | |
| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | |
| CURRENT_SQL_DIGEST_TEXT | text | YES | | NULL | |
| STATE | enum('Idle','Running','LockWaiting','Committing','RollingBack') | YES | | NULL | |
| WAITING_START_TIME | timestamp(6) | YES | | NULL | |
| MEM_BUFFER_KEYS | bigint(64) | YES | | NULL | |
| MEM_BUFFER_BYTES | bigint(64) | YES | | NULL | |
| SESSION_ID | bigint(21) unsigned | YES | | NULL | |
| USER | varchar(16) | YES | | NULL | |
| DB | varchar(64) | YES | | NULL | |
| ALL_SQL_DIGESTS | text | YES | | NULL | |
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+
The meaning of each column field in the TIDB_TRX table is as follows:
ID: The transaction ID, which is thestart_ts(start timestamp) of the transaction.START_TIME: The start time of the transaction, which is the physical time corresponding to thestart_tsof the transaction.CURRENT_SQL_DIGEST: The digest of the SQL statement currently being executed in the transaction.CURRENT_SQL_DIGEST_TEXT: The normalized form of the SQL statement currently being executed by the transaction, that is, the SQL statement without arguments and format. It corresponds toCURRENT_SQL_DIGEST.STATE: The current state of the transaction. The possible values include:Idle: The transaction is in an idle state, that is, it is waiting for the user to input a query.Running: The transaction is executing a query.LockWaiting: The transaction is waiting for the pessimistic lock to be acquired. Note that the transaction enters this state at the beginning of the pessimistic locking operation, no matter whether it is blocked by other transactions or not.Committing: The transaction is in the process of commit.RollingBack: The transaction is being rolled back.
WAITING_START_TIME: When the value ofSTATEisLockWaiting, this column shows the start time of the waiting.MEM_BUFFER_KEYS: The number of keys written into the memory buffer by the current transaction.MEM_BUFFER_BYTES: The total number of key-value bytes written into the memory buffer by the current transaction.SESSION_ID: The ID of the session to which this transaction belongs.USER: The name of the user who performs the transaction.DB: The current default database name of the session in which the transaction is executed.ALL_SQL_DIGESTS: The digest list of statements that have been executed by the transaction. The list is shown as a string array in JSON format. Each transaction records at most the first 50 statements. Using theTIDB_DECODE_SQL_DIGESTSfunction, you can convert the information in this column into a list of corresponding normalized SQL statements.
- Only users with the PROCESS privilege can obtain the complete information in this table. Users without the PROCESS privilege can only query information of the transactions performed by the current user.
- The information (SQL digest) in the
CURRENT_SQL_DIGESTandALL_SQL_DIGESTScolumns is the hash value calculated from the normalized SQL statement. The information in theCURRENT_SQL_DIGEST_TEXTcolumn and the result returned from theTIDB_DECODE_SQL_DIGESTSfunction are internally queried from the statements summary tables, so it is possible that the corresponding statement cannot be found internally. For the detailed description of SQL digests and the statements summary tables, see Statement Summary Tables. - The
TIDB_DECODE_SQL_DIGESTSfunction call has a high overhead. If the function is called to query historical SQL statements for a large number of transactions, the query might take a long time. If the cluster is large with many concurrent transactions, avoid directly using this function on theALL_SQL_DIGESTcolumn while querying the full table ofTIDB_TRX. This means to avoid an SQL statement likeselect *, tidb_decode_sql_digests(all_sql_digests) from tidb_trx. - Currently the
TIDB_TRXtable does not support showing information of TiDB internal transactions.
Example
select * from information_schema.tidb_trx\G
*************************** 1. row ***************************
ID: 426789913200689153
START_TIME: 2021-08-04 10:51:54.883000
CURRENT_SQL_DIGEST: NULL
CURRENT_SQL_DIGEST_TEXT: NULL
STATE: Idle
WAITING_START_TIME: NULL
MEM_BUFFER_KEYS: 1
MEM_BUFFER_BYTES: 29
SESSION_ID: 7
USER: root
DB: test
ALL_SQL_DIGESTS: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5","04fa858fa491c62d194faec2ab427261cc7998b3f1ccf8f6844febca504cb5e9","b83710fa8ab7df8504920e8569e48654f621cf828afbe7527fd003b79f48da9e"]
*************************** 2. row ***************************
ID: 426789921471332353
START_TIME: 2021-08-04 10:52:26.433000
CURRENT_SQL_DIGEST: 38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821
CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ?
STATE: LockWaiting
WAITING_START_TIME: 2021-08-04 10:52:35.106568
MEM_BUFFER_KEYS: 0
MEM_BUFFER_BYTES: 0
SESSION_ID: 9
USER: root
DB: test
ALL_SQL_DIGESTS: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5","38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821"]
2 rows in set (0.01 sec)
From the query result of this example, you can see that: the current node has two on-going transactions. One transaction is in the idle state (STATE is Idle and CURRENT_SQL_DIGEST is NULL), and this transaction has executed 3 statements (there are three records in the ALL_SQL_DIGESTS list, which are the digests of the three SQL statements that have been executed). Another transaction is executing a statement and waiting for the lock (STATE is LockWaiting and WAITING_START_TIME shows the start time of the waiting lock). The transaction has executed 2 statements, and the statement currently being executed is in the form of "update `t` set `v` = `v` + ? where `id` = ?".
select id, all_sql_digests, tidb_decode_sql_digests(all_sql_digests) as all_sqls from information_schema.tidb_trx\G
*************************** 1. row ***************************
id: 426789913200689153
all_sql_digests: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5","04fa858fa491c62d194faec2ab427261cc7998b3f1ccf8f6844febca504cb5e9","b83710fa8ab7df8504920e8569e48654f621cf828afbe7527fd003b79f48da9e"]
all_sqls: ["begin","insert into `t` values ( ... )","update `t` set `v` = `v` + ?"]
*************************** 2. row ***************************
id: 426789921471332353
all_sql_digests: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5","38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821"]
all_sqls: ["begin","update `t` set `v` = `v` + ? where `id` = ?"]
This query calls the TIDB_DECODE_SQL_DIGESTS function on the ALL_SQL_DIGESTS column of the TIDB_TRX table, and converts the SQL digest array into an array of normalized SQL statement through the system internal query. This helps you visually obtain the information of the statements that have been historically executed by the transaction. However, note that the above query scans the entire table of TIDB_TRX and calls the TIDB_DECODE_SQL_DIGESTS function for each row. Calling the TIDB_DECODE_SQL_DIGESTS function has a high overhead. Therefore, if many concurrent transactions exist in the cluster, try to avoid this type of query.
CLUSTER_TIDB_TRX
The TIDB_TRX table only provides information about the transactions that are being executed on a single TiDB node. If you want to view the information of the transactions that are being executed on all TiDB nodes in the entire cluster, you need to query the CLUSTER_TIDB_TRX table. Compared with the query result of the TIDB_TRX table, the query result of the CLUSTER_TIDB_TRX table includes an extra INSTANCE field. The INSTANCE field displays the IP address and port of each node in the cluster, which is used to distinguish the TiDB nodes where the transactions are located.
USE information_schema;
DESC cluster_tidb_trx;
mysql> desc cluster_tidb_trx;
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+
| INSTANCE | varchar(64) | YES | | NULL | |
| ID | bigint(21) unsigned | NO | PRI | NULL | |
| START_TIME | timestamp(6) | YES | | NULL | |
| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | |
| CURRENT_SQL_DIGEST_TEXT | text | YES | | NULL | |
| STATE | enum('Idle','Running','LockWaiting','Committing','RollingBack') | YES | | NULL | |
| WAITING_START_TIME | timestamp(6) | YES | | NULL | |
| MEM_BUFFER_KEYS | bigint(64) | YES | | NULL | |
| MEM_BUFFER_BYTES | bigint(64) | YES | | NULL | |
| SESSION_ID | bigint(21) unsigned | YES | | NULL | |
| USER | varchar(16) | YES | | NULL | |
| DB | varchar(64) | YES | | NULL | |
| ALL_SQL_DIGESTS | text | YES | | NULL | |
+-------------------------+-----------------------------------------------------------------+------+------+---------+-------+