From b6963a84aeb0cc8a4a87d8b342afd8dc9cfc10eb Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Tue, 17 Aug 2021 14:20:02 +0800 Subject: [PATCH 01/11] Update documents of lock view for sprint 4 --- functions-and-operators/tidb-functions.md | 70 ++++++ .../information-schema-data-lock-waits.md | 80 +++---- .../information-schema-deadlocks.md | 212 +++++++++--------- .../information-schema-tidb-trx.md | 157 +++++++------ tidb-configuration-file.md | 5 + troubleshoot-lock-conflicts.md | 121 +++++----- 6 files changed, 368 insertions(+), 277 deletions(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 07a20be367a30..82b93f0b7153b 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -257,3 +257,73 @@ Check Table Before Drop: false ### MySQL compatibility The `TIDB_VERSION` function is TiDB-specific and not compatible with MySQL. If MySQL compatibility is required, you can also use `VERSION` to get version information, but the result does not contain build details. + +## TIDB_DECODE_SQL_DIGESTS + +The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL statements (a form without format and parameter) corresponding to the set of SQL digests in the cluster. This function accepts 1 or 2 parameters: + +* `digests`: The string type, this parameter should conform to the format of a JSON string array, and each string in the array should be a SQL Digest. +* `stmtTruncateLength`: Optional parameter, integer type, used to limit the length of each SQL statement in the returned result, and it will be truncated if it exceeds the specified length. 0 means unlimited length. + +This function returns a string, which is in the format of a JSON string array. The *i* item in the array is the statement corresponding to the *i* element in the `digests` parameter. If an item in the digests` parameter `is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. + +> **Note:** +> +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can use this function. +> * When `TIDB_DECODE_SQL_DIGESTS` is executed, TiDB queries the statement corresponding to each SQL digest from the series of statement summary tables, so there is no guarantee that the corresponding statement can always be queried for any SQL digest. Only the statements executed in the cluster might be queried, and whether these SQL statements can be queried or not is affected by the related configuration of the statement summary table. For the detailed description of the statement summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), directly using this function might cause the query to run longer time. Use it with caution. +> * This function has a high overhead because every time it is called, it internally queries the tables `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY` and, `CLUSTER_STATEMENTS_SUMMARY_HISTORY`, which also involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. + +### Synopsis + +```ebnf+diagram +DecodeSQLDigestsExpr ::= + "TIDB_DECODE_SQL_DIGESTS" "(" digests ( "," stmtTruncateLength )? ")" +``` + +### Example + +{{< copyable "sql" >}} + +```sql +set @digests = '["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5","38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821","e5796985ccafe2f71126ed6c0ac939ffa015a8c0744a24b7aee6d587103fd2f7"]'; + +select tidb_decode_sql_digests(@digests); +``` + +```sql ++------------------------------------+ +| tidb_decode_sql_digests(@digests) | ++------------------------------------+ +| ["begin",null,"select * from `t`"] | ++------------------------------------+ +1 row in set (0.00 sec) +``` + +In the above example, the parameter is a JSON array containing 3 SQL digests, and the corresponding SQL statements are the three items in the query results. But the SQL statement corresponding to the second SQL digest cannot be found from the cluster, so the second item in the result is `null`. + +{{< copyable "sql" >}} + +```sql +select tidb_decode_sql_digests(@digests, 10); +``` + +```sql ++---------------------------------------+ +| tidb_decode_sql_digests(@digests, 10) | ++---------------------------------------+ +| ["begin",null,"select * f..."] | ++---------------------------------------+ +1 row in set (0.01 sec) +``` + +The above call specifies the second parameter (that is, the truncation length) as 10, and the length of the third statement in the query result is greater than 10. Therefore, only the first 10 characters are retained and `"..." is added at the end, which indicates that truncation has occurred. + +### MySQL compatibility + +`TIDB_DECODE_SQL_DIGESTS` is a TiDB-specific function and not compatible with MySQL. + +### See also + +- [`Statement Summary Tables`](/statement-summary-tables.md) +- [`INFORMATION_SCHEMA.TIDB_TRX`](/information-schema/information-schema-tidb-trx.md) diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index 71cba4cda5758..33a471f2005d3 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -7,10 +7,6 @@ summary: Learn the `DATA_LOCK_WAITS` information_schema table. The `DATA_LOCK_WAITS` table shows the ongoing pessimistic locks waiting on all TiKV nodes in the cluster. -> **Warning:** -> -> Currently, this is an experimental feature. The definition and behavior of the table structure might have major changes in future releases. - {{< copyable "sql" >}} ```sql @@ -22,24 +18,55 @@ DESC data_lock_waits; +------------------------+---------------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +------------------------+---------------------+------+------+---------+-------+ -| KEY | varchar(64) | NO | | NULL | | +| KEY | text | NO | | NULL | | +| KEY_INFO | text | YES | | NULL | | | TRX_ID | bigint(21) unsigned | NO | | NULL | | | CURRENT_HOLDING_TRX_ID | bigint(21) unsigned | NO | | NULL | | | SQL_DIGEST | varchar(64) | YES | | NULL | | +| SQL_DIGEST_TEXT | text | YES | | NULL | | +------------------------+---------------------+------+------+---------+-------+ ``` The meaning of each column field in the `DATA_LOCK_WAITS` table is as follows: -* `KEY`: The KEY that is waiting for the lock and displayed in the form of hexadecimal string. +* `KEY`: The key that is waiting for the lock and displayed in the form of hexadecimal string. +* `KEY_INFO`: The detailed information of `KEY`. See the [KEY_INFO](#key_info) section. * `TRX_ID`: The ID of the transaction that is waiting for the lock. This ID is also the `start_ts` of the transaction. * `CURRENT_HOLDING_TRX_ID`: The ID of the transaction that currently holds the lock. This ID is also the `start_ts` of the transaction. * `SQL_DIGEST`: The digest of the SQL statement that is currently blocked in the lock-waiting transaction. +* `SQL_DIGEST_TEXT`: The normalized SQL statement (the SQL statement without parameters and format) that is currently blocked in the lock-waiting transaction. It corresponds to `SQL_DIGEST`. > **Warning:** > -> * The information in this table is obtained in real time from all TiKV nodes during the query. Currently, even if the `WHERE` condition is added, TiDB might still collect information from all TiKV nodes. If the cluster is large and the load is high, querying this table might cause a potential risk of performance jitter. Therefore, use this table according to your actual situation. -> * The information from different TiKV nodes is NOT guaranteed to be the snapshot at the same point in time. +> * Only the users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can query this table. +> * The information in the `DATA_LOCK_WAITS` table is obtained in real time from all TiKV nodes during the query. Currently, even if a query has the `WHERE` condition, the information collection is still performed on all TiKV nodes. If your cluster is large and the load is high, querying this table might cause potential risk of performance jitter. Therefore, use it according to your actual situation. +> * Information from different TiKV nodes is not necessarily in snapshots of the same point in time. +> * The information (SQL digest) in the `SQL_DIGEST` column is the hash value calculated after the SQL statement is normalized. The information in the `SQL_DIGEST_TEXT` column is internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). + +## `KEY_INFO` + +The `KEY_INFO` column shows the detailed information of the key in the `KEY` column. The information is shown in the JSON format. The contained fields are described as follows: + +* `"db_id"`: The ID of the schema to which the key belongs. +* `"db_name"`: The name of the schema to which the key belongs. +* `"table_id"`: The ID of the table to which the key belongs. +* `"table_name"`: The name of the table to which the key belongs. +* `"partition_id"`: The ID of the partition where the key is located. +* `"partition_name"`: The name of the partition where the key is located. +* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). Its possible values ​​are as follows: + * `"int"`: The handle is of the int type, which means that the handle is the row ID. + * `"common"`: The handle of the non-int64 type. This type is shown in the non-int primary key when clustered index is enabled. + * `"unknown"`: The handle type that is currently not supported. +* `"handle_value"`: The handle value. +* `"index_id"`: The index ID to which the index key (the key that stores the index) belongs. +* `"index_name"`: The name of the index to which the index key belongs. +* `"index_values"`: The index value in the index key. + +In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information from `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. + +> **Note:** +> +> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one of a table partition. ## Example @@ -51,36 +78,13 @@ select * from information_schema.data_lock_waits\G ```sql *************************** 1. row *************************** - KEY: 7480000000000000355f728000000000000002 - TRX_ID: 425405024158875649 -CURRENT_HOLDING_TRX_ID: 425405016242126849 - SQL_DIGEST: f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22 -2 rows in set (0.01 sec) + KEY: 7480000000000000355F728000000000000001 + KEY_INFO: {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"1"} + TRX_ID: 426790594290122753 +CURRENT_HOLDING_TRX_ID: 426790590082449409 + SQL_DIGEST: 38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821 + SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? +1 row in set (0.01 sec) ``` The above query result shows that the transaction of the ID `425405024158875649` was trying to obtain the pessimistic lock on the key `7480000000000000355f728000000000000002` when the statement with digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` was being executed, but the lock on this key was held by the transaction of the ID `425405016242126849`. - -## SQL Digest - -The `DATA_LOCK_WAITS` table records the SQL digest but not the original SQL statement. - -SQL digest is the hash value of the normalized SQL statement. To find the original SQL statement corresponding to the SQL digest, perform one of the following operations: - -- For the statements executed on the current TiDB node in the recent period of time, you can find the corresponding original SQL statement in the `STATEMENTS_SUMMARY` or `STATEMENTS_SUMMARY_HISTORY` table according to the SQL digest. -- For the statements executed on all TiDB nodes in the entire cluster in the recent period of time, you can find the corresponding SQL statement in the `CLUSTER_STATEMENTS_SUMMARY` or `CLUSTER_STATEMENTS_SUMMARY_HISTORY` table according to the SQL digest. - -{{< copyable "sql" >}} - -```sql -select digest, digest_text from information_schema.statements_summary where digest = "f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2"; -``` - -```sql -+------------------------------------------------------------------+---------------------------------------+ -| digest | digest_text | -+------------------------------------------------------------------+---------------------------------------+ -| f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2 | update `t` set `v` = ? where `id` = ? | -+------------------------------------------------------------------+---------------------------------------+ -``` - -For detailed description of SQL digest, `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY`, and `CLUSTER_STATEMENTS_SUMMARY_HISTORY` tables, see [Statement Summary Tables](/statement-summary-tables.md). diff --git a/information-schema/information-schema-deadlocks.md b/information-schema/information-schema-deadlocks.md index 6133ac3988198..b636da617cd59 100644 --- a/information-schema/information-schema-deadlocks.md +++ b/information-schema/information-schema-deadlocks.md @@ -7,10 +7,6 @@ summary: Learn the `DEADLOCKS` information_schema table. The `DEADLOCKS` table shows the information of the several deadlock errors that have occurred recently on the current TiDB node. -> **Warning:** -> -> Currently, this is an experimental feature. The definition and behavior of the table structure might have major changes in future releases. - {{< copyable "sql" >}} ```sql @@ -22,14 +18,19 @@ DESC deadlocks; +--------------------+---------------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +--------------------+---------------------+------+------+---------+-------+ -| DEADLOCK_ID | bigint(21) | NO | | NULL | | -| OCCUR_TIME | timestamp(6) | YES | | NULL | | -| RETRYABLE | tinyint(1) | NO | | NULL | | -| TRY_LOCK_TRX_ID | bigint(21) unsigned | NO | | NULL | | -| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | | -| KEY | text | YES | | NULL | | -| TRX_HOLDING_LOCK | bigint(21) unsigned | NO | | NULL | | -+--------------------+---------------------+------+------+---------+-------+ ++-------------------------+---------------------+------+------+---------+-------+ +| Field | Type | Null | Key | Default | Extra | ++-------------------------+---------------------+------+------+---------+-------+ +| DEADLOCK_ID | bigint(21) | NO | | NULL | | +| OCCUR_TIME | timestamp(6) | YES | | NULL | | +| RETRYABLE | tinyint(1) | NO | | NULL | | +| TRY_LOCK_TRX_ID | bigint(21) unsigned | NO | | NULL | | +| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | | +| CURRENT_SQL_DIGEST_TEXT | text | YES | | NULL | | +| KEY | text | YES | | NULL | | +| KEY_INFO | text | YES | | NULL | | +| TRX_HOLDING_LOCK | bigint(21) unsigned | NO | | NULL | | ++-------------------------+---------------------+------+------+---------+-------+ ``` The `DEADLOCKS` table uses multiple rows to show the same deadlock event, and each row displays the information about one of the transactions involved in the deadlock event. If the TiDB node records multiple deadlock errors, each error is distinguished using the `DEADLOCK_ID` column. The same `DEADLOCK_ID` indicates the same deadlock event. Note that `DEADLOCK_ID` **does not guarantee global uniqueness and will not be persisted**. It only shows the same deadlock event in the same result set. @@ -38,78 +39,51 @@ The meaning of each column field in the `DEADLOCKS` table is as follows: * `DEADLOCK_ID`: The ID of the deadlock event. When multiple deadlock errors exist in the table, you can use this column to distinguish rows that belong to different deadlock errors. * `OCCUR_TIME`: The time when the deadlock error occurs. -* `RETRYABLE`: Whether the deadlock error can be retried. Currently, TiDB does not support collecting the information of the retryable deadlock error, so the value of this field is always `0`. For the description of retryable deadlock errors, see the [Retryable deadlock errors](#retryable-deadlock-errors) section. +* `RETRYABLE`: Whether the deadlock error can be retried. For the description of retryable deadlock errors, see the [Retryable deadlock errors](#retryable-deadlock-errors) section. * `TRY_LOCK_TRX_ID`: The ID of the transaction that tries to acquire lock. This ID is also the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the lock-acquiring transaction. +* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed in the lock-adding transaction. * `KEY`: The blocked key that the transaction tries to lock. The value of this field is displayed in the form of hexadecimal string. +* `KEY_INFO`: The detailed information of `KEY`. See the [KEY_INFO](#key_info) section. * `TRX_HOLDING_LOCK`: The ID of the transaction that currently holds the lock on the key and causes blocking. This ID is also the `start_ts` of the transaction. To adjust the maximum number of deadlock events that can be recorded in the `DEADLOCKS` table, adjust the [`pessimistic-txn.deadlock-history-capacity`](/tidb-configuration-file.md#deadlock-history-capacity) configuration in the TiDB configuration file. By default, the information of the recent 10 deadlock events is recorded in the table. -## Example 1 - -Assume that the table definition and the initial data are as follows: - -{{< copyable "sql" >}} - -```sql -create table t (id int primary key, v int); -insert into t values (1, 10), (2, 20); -``` - -Execute the two transactions in the following order: - -| Transaction 1 | Transaction 2 | Description | -|--------------------------------------|--------------------------------------|----------------------| -| `update t set v = 11 where id = 1;` | | | -| | `update t set v = 21 where id = 2;` | | -| `update t set v = 12 where id = 2;` | | Transaction 1 gets blocked. | -| | `update t set v = 22 where id = 1;` | Transaction 2 reports a deadlock error. | - -Next, transaction 2 reports a deadlock error. At this time, query the `DEADLOCKS` table: - -{{< copyable "sql" >}} - -```sql -select * from information_schema.deadlocks; -``` - -The expected output is as follows: - -```sql -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | KEY | TRX_HOLDING_LOCK | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904707 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000002 | 425405959304904708 | -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904708 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000001 | 425405959304904707 | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -``` - -Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that the transaction of the ID `425405959304904707` is blocked on the key of `"7480000000000000385F728000000000000002"` by the transaction of the ID `"425405959304904708"`. The second row shows that the transaction of the ID `"425405959304904708"` is blocked on the key of `"7480000000000000385F728000000000000001"` by the transaction of the ID `425405959304904707`, which constitutes mutual blocking and forms a deadlock. - -## Example 2 - -Assume that you query the `DEADLOCKS` table and get the following result: - -```sql -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | KEY | TRX_HOLDING_LOCK | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904707 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000002 | 425405959304904708 | -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904708 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000001 | 425405959304904707 | -| 2 | 2021-06-04 08:22:56.795410 | 0 | 425405961664462853 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000002 | 425405961664462854 | -| 2 | 2021-06-04 08:22:56.795410 | 0 | 425405961664462854 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000003 | 425405961664462855 | -| 2 | 2021-06-04 08:22:56.795410 | 0 | 425405961664462855 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000001 | 425405961664462853 | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -``` +> **Warning:** +> +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can query this table. +> * The information (SQL digest) in the `CURRENT_SQL_DIGEST` column is the hash value calculated after the SQL statement is normalized. The information in the `CURRENT_SQL_DIGEST_TEXT` column is internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). + +## `KEY_INFO` + +The `KEY_INFO` column shows the detailed information of the key in the `KEY` column. The information is shown in the JSON format. The contained fields are described as follows: + +* `"db_id"`: The ID of the schema to which the key belongs. +* `"db_name"`: The name of the schema to which the key belongs. +* `"table_id"`: The ID of the table to which the key belongs. +* `"table_name"`: The name of the table to which the key belongs. +* `"partition_id"`: The ID of the partition where the key is located. +* `"partition_name"`: The name of the partition where the key is located. +* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). Its possible values ​​are as follows: + * `"int"`: The handle is of the int type, which means that the handle is the row ID. + * `"common"`: The handle of the non-int64 type. This type is shown in the non-int primary key when clustered index is enabled. + * `"unknown"`: The handle type that is currently not supported. +* `"handle_value"`: The handle value. +* `"index_id"`: The index ID to which the index key (the key that stores the index) belongs. +* `"index_name"`: The name of the index to which the index key belongs. +* `"index_values"`: The index value in the index key. + +In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information from `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. -The `DEADLOCK_ID` column in the above query result shows that the first two rows together represent the information of a deadlock error, and the two transactions that wait for each other form the deadlock. The next three rows together represent another deadlock information, and the three transactions that wait in a cycle form the deadlock. +> **Note:** +> +> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one of a table partition. ## Retryable deadlock errors > **Note:** > -> Currently, TiDB does not support collecting retryable deadlock errors in the `DEADLOCKS` table. +> The `DEADLOCKS` table does not collect the information of retryable deadlock errors by default. If you want the table to collect the retryable deadlock error information, you can adjust the value of [`pessimistic-txn.deadlock-history-collect-retryable`](/tidb-configuration-file.md#deadlock-history-collect-retryable) in the TiDB configuration file. When transaction A is blocked by a lock already held by transaction B, and transaction B is directly or indirectly blocked by the lock held by the current transaction A, a deadlock error will occur. In this deadlock, there might be two cases: @@ -146,55 +120,91 @@ For this case, because the statement of transaction A that blocks other transact When a retryable deadlock occurs, the internal automatic retry will not cause a transaction error, so it is transparent to the client. However, if this situation occurs frequently, the performance might be affected. When this occurs, you can see `single statement deadlock, retry statement` in the TiDB log. -## CLUSTER_DEADLOCKS +## Example 1 -The `CLUSTER_DEADLOCKS` table returns information about the recent deadlock errors on each TiDB node in the entire cluster, which is the information of the `DEADLOCKS` table on each node combined together. `CLUSTER_DEADLOCKS` also contains an additional `INSTANCE` column to display the IP address and port of the node to distinguish between different TiDB nodes. +Assume that the table definition and the initial data are as follows: -Note that, because `DEADLOCK_ID` does not guarantee global uniqueness, in the query result of the `CLUSTER_DEADLOCKS` table, you need to use the `INSTANCE` and `DEADLOCK_ID` together to distinguish the information of different deadlock errors in the result set. +{{< copyable "sql" >}} + +```sql +create table t (id int primary key, v int); +insert into t values (1, 10), (2, 20); +``` + +Execute the two transactions in the following order: + +| Transaction 1 | Transaction 2 | Description | +|--------------------------------------|--------------------------------------|----------------------| +| `update t set v = 11 where id = 1;` | | | +| | `update t set v = 21 where id = 2;` | | +| `update t set v = 12 where id = 2;` | | Transaction 1 gets blocked. | +| | `update t set v = 22 where id = 1;` | Transaction 2 reports a deadlock error. | + +Next, transaction 2 reports a deadlock error. At this time, query the `DEADLOCKS` table: {{< copyable "sql" >}} ```sql -USE information_schema; -DESC cluster_deadlocks; +select * from information_schema.deadlocks; ``` +The expected output is as follows: + ```sql -+--------------------+---------------------+------+------+---------+-------+ -| Field | Type | Null | Key | Default | Extra | -+--------------------+---------------------+------+------+---------+-------+ -| INSTANCE | varchar(64) | YES | | NULL | | -| DEADLOCK_ID | bigint(21) | NO | | NULL | | -| OCCUR_TIME | timestamp(6) | YES | | NULL | | -| RETRYABLE | tinyint(1) | NO | | NULL | | -| TRY_LOCK_TRX_ID | bigint(21) unsigned | NO | | NULL | | -| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | | -| KEY | text | YES | | NULL | | -| TRX_HOLDING_LOCK | bigint(21) unsigned | NO | | NULL | | -+--------------------+---------------------+------+------+---------+-------+ ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | CURRENT_SQL_DIGEST_TEXT | KEY | KEY_INFO | TRX_HOLDING_LOCK | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406216 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000002 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"2"} | 426812829645406217 | +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406217 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000001 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"1"} | 426812829645406216 | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +``` + +Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that the transaction of the ID `425405959304904707` is blocked on the key of `"7480000000000000385F728000000000000002"` by the transaction of the ID `"425405959304904708"`. The second row shows that the transaction of the ID `"425405959304904708"` is blocked on the key of `"7480000000000000385F728000000000000001"` by the transaction of the ID `425405959304904707`, which constitutes mutual blocking and forms a deadlock. + +## Example 2 + +Assume that you query the `DEADLOCKS` table and get the following result: + +```sql ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | CURRENT_SQL_DIGEST_TEXT | KEY | KEY_INFO | TRX_HOLDING_LOCK | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406216 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000002 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"2"} | 426812829645406217 | +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406217 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000001 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"1"} | 426812829645406216 | +| 2 | 2021-08-05 11:09:21.252154 | 0 | 426812832017809412 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000002 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"2"} | 426812832017809413 | +| 2 | 2021-08-05 11:09:21.252154 | 0 | 426812832017809413 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000003 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"3"} | 426812832017809414 | +| 2 | 2021-08-05 11:09:21.252154 | 0 | 426812832017809414 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000001 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"1"} | 426812832017809412 | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -## SQL Digest +The `DEADLOCK_ID` column in the above query result shows that the first two rows together represent the information of a deadlock error, and the two transactions that wait for each other form the deadlock. The next three rows together represent another deadlock information, and the three transactions that wait in a cycle form the deadlock. -The `DEADLOCKS` table records the SQL digest but not the original SQL statement. +## CLUSTER_DEADLOCKS -SQL digest is the hash value after the SQL normalization. To find the original SQL statement corresponding to the SQL digest, perform one of the following operations: +The `CLUSTER_DEADLOCKS` table returns information about the recent deadlock errors on each TiDB node in the entire cluster, which is the information of the `DEADLOCKS` table on each node combined together. `CLUSTER_DEADLOCKS` also contains an additional `INSTANCE` column to display the IP address and port of the node to distinguish between different TiDB nodes. -- For the statements executed on the current TiDB node in the recent period of time, you can find the corresponding original SQL statement in the `STATEMENTS_SUMMARY` or `STATEMENTS_SUMMARY_HISTORY` table according to the SQL digest. -- For the statements executed on all TiDB nodes in the entire cluster in the recent period of time, you can find the corresponding SQL statement in the `CLUSTER_STATEMENTS_SUMMARY` or `CLUSTER_STATEMENTS_SUMMARY_HISTORY` table according to the SQL digest. +Note that, because `DEADLOCK_ID` does not guarantee global uniqueness, in the query result of the `CLUSTER_DEADLOCKS` table, you need to use the `INSTANCE` and `DEADLOCK_ID` together to distinguish the information of different deadlock errors in the result set. {{< copyable "sql" >}} ```sql -select digest, digest_text from information_schema.statements_summary where digest = "f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2"; +USE information_schema; +DESC cluster_deadlocks; ``` ```sql -+------------------------------------------------------------------+---------------------------------------+ -| digest | digest_text | -+------------------------------------------------------------------+---------------------------------------+ -| f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2 | update `t` set `v` = ? where `id` = ? | -+------------------------------------------------------------------+---------------------------------------+ ++-------------------------+---------------------+------+------+---------+-------+ +| Field | Type | Null | Key | Default | Extra | ++-------------------------+---------------------+------+------+---------+-------+ +| INSTANCE | varchar(64) | YES | | NULL | | +| DEADLOCK_ID | bigint(21) | NO | | NULL | | +| OCCUR_TIME | timestamp(6) | YES | | NULL | | +| RETRYABLE | tinyint(1) | NO | | NULL | | +| TRY_LOCK_TRX_ID | bigint(21) unsigned | NO | | NULL | | +| CURRENT_SQL_DIGEST | varchar(64) | YES | | NULL | | +| CURRENT_SQL_DIGEST_TEXT | text | YES | | NULL | | +| KEY | text | YES | | NULL | | +| KEY_INFO | text | YES | | NULL | | +| TRX_HOLDING_LOCK | bigint(21) unsigned | NO | | NULL | | ++-------------------------+---------------------+------+------+---------+-------+ ``` - -For detailed description of SQL digest, `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY`, and `CLUSTER_STATEMENTS_SUMMARY_HISTORY` tables, see [Statement Summary Tables](/statement-summary-tables.md). diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index 1a9008bc49f98..b683831cf3c6c 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -7,11 +7,6 @@ summary: Learn the `TIDB_TRX` information_schema table. The `TIDB_TRX` table provides information about the transactions currently being executed on the TiDB node. -> **Warning:** -> -> * Currently, this is an experimental feature. The definition and behavior of the table structure might have major changes in future releases. -> * Currently, the `TIDB_TRX` table does not support displaying information of TiDB's internal transactions. - {{< copyable "sql" >}} ```sql @@ -20,21 +15,22 @@ DESC tidb_trx; ``` ```sql -+--------------------+---------------------------------------------------------+------+------+---------+-------+ -| 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 | | -| STATE | enum('Normal','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 | | -+--------------------+---------------------------------------------------------+------+------+---------+-------+ ++-------------------------+-----------------------------------------------------------------+------+------+---------+-------+ +| 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: @@ -42,8 +38,10 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: * `ID`: The transaction ID, which is the `start_ts` (start timestamp) of the transaction. * `START_TIME`: The start time of the transaction, which is the physical time corresponding to the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the transaction. +* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed by the transaction, that is, the SQL statement without parameters and format. It corresponds to `CURRENT_SQL_DIGEST`. * `STATE`: The current state of the transaction. The possible values ​​include: - * `Normal`: The transaction is being executed normally or in an idle state. + * `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. @@ -53,7 +51,14 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: * `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 in this transaction. For each transaction, the first 50 statements at most are recorded. +* `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 the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function, you can convert the information in this column into a list of corresponding normalized SQL statements. + +> **Note:** +> +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can obtain the complete information in this table. Users without the PROCESS permission can only query information of the transactions performed by the current user. +> * The information (SQL digest) in the `CURRENT_SQL_DIGEST` and `ALL_SQL_DIGESTS` columns is the hash value calculated after the SQL statement is normalized. The information in the `CURRENT_SQL_DIGEST_TEXT` column and the result returned from the `TIDB_DECODE_SQL_DIGESTS` function are internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * The [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function 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 the `ALL_SQL_DIGEST` column while querying the full table of `TIDB_TRX`. This means to avoid SQL statement like ``select *, tidb_decode_sql_digests(all_sql_digests) from tidb_trx``. +> * Currently the `TIDB_TRX` table does not support showing information related to TiDB transactions. ## Example @@ -65,73 +70,81 @@ select * from information_schema.tidb_trx\G ```sql *************************** 1. row *************************** - ID: 425403705115541506 - START_TIME: 2021-06-04 05:59:10.691000 -CURRENT_SQL_DIGEST: NULL - STATE: Normal -WAITING_START_TIME: NULL - MEM_BUFFER_KEYS: 2 - MEM_BUFFER_BYTES: 48 - SESSION_ID: 7 - USER: root - DB: test - ALL_SQL_DIGESTS: [e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02ad5, 04fa858fa491c62d194faec2ab427261cc7998b3f1ccf8f6844febca504cb5e9, f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2] -1 row in set (0.00 sec) + 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) ``` -The query result of the above example indicates that a transaction is being executed on the current node (the `STATE` is `Normal`), and this transaction is currently idle (`CURRENT_SQL_DIGEST` is `NULL`). This transaction has executed three statements (there are three records in the `ALL_SQL_DIGESTS` list and they are the digests of the three executed statements). - -## 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 contains 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 node where the transaction is located. +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 similar to ``"update `t` set `v` = `v` +? where `id` = ?"``. where `id` = ?"``。 {{< copyable "sql" >}} ```sql -USE information_schema; -DESC cluster_tidb_trx; +select id, all_sql_digests, tidb_decode_sql_digests(all_sql_digests) as all_sqls from information_schema.tidb_trx\G ``` ```sql -+--------------------+---------------------------------------------------------+------+------+---------+-------+ -| 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 | | -| STATE | enum('Normal','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 | | -+--------------------+---------------------------------------------------------+------+------+---------+-------+ +*************************** 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` = ?"] ``` -## SQL Digest - -The `TIDB_TRX` table only records SQL digests, not the original SQL statement. - -SQL digest is the hash value after the SQL normalization. To find the original SQL statement corresponding to the SQL digest, perform one of the following operations: +## CLUSTER_TIDB_TRX -- For the statements executed on the current TiDB node in the recent period of time, you can find the corresponding orginal SQL statement from the SQL digest in `STATEMENTS_SUMMARY` or `STATEMENTS_SUMMARY_HISTORY`. -- For the statements executed on all TiDB nodes in the entire cluster in the recent period of time, you can find the corresponding SQL statement from the SQL digest in `CLUSTER_STATEMENTS_SUMMARY` or `CLUSTER_STATEMENTS_SUMMARY_HISTORY`. +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 contains 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 node where the transaction is located. {{< copyable "sql" >}} ```sql -select digest, digest_text from information_schema.statements_summary where digest = "f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2"; +USE information_schema; +DESC cluster_tidb_trx; ``` ```sql -+------------------------------------------------------------------+---------------------------------------+ -| digest | digest_text | -+------------------------------------------------------------------+---------------------------------------+ -| f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb2 | update `t` set `v` = ? where `id` = ? | -+------------------------------------------------------------------+---------------------------------------+ +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 | | ++-------------------------+-----------------------------------------------------------------+------+------+---------+-------+ ``` - -For detailed description of SQL digest, `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY`, and `CLUSTER_STATEMENTS_SUMMARY_HISTORY` tables, see [Statement Summary Tables](/statement-summary-tables.md). diff --git a/tidb-configuration-file.md b/tidb-configuration-file.md index c856bb976f7b1..566c351b5fdcf 100644 --- a/tidb-configuration-file.md +++ b/tidb-configuration-file.md @@ -638,6 +638,11 @@ For pessimistic transaction usage, refer to [TiDB Pessimistic Transaction Mode]( + Minimum value: `0` + Maximum value: `10000` +### deadlock-history-collect-retryable + ++ Controls whether the [`INFORMATION_SCHEMA.DEADLOCKS`](/information-schema/information-schema-deadlocks.md) table collects the information of retryable deadlock errors. For the description of retryable deadlock errors, see [Retryable deadlock errors](/information-schema/information-schema-deadlocks.md#retryable-deadlock-errors). ++ Default value: `false` + ## experimental The `experimental` section, introduced in v3.1.0, describes configurations related to the experimental features of TiDB. diff --git a/troubleshoot-lock-conflicts.md b/troubleshoot-lock-conflicts.md index 16646e062855f..36cd5d3427e42 100644 --- a/troubleshoot-lock-conflicts.md +++ b/troubleshoot-lock-conflicts.md @@ -241,9 +241,9 @@ Since v5.1, TiDB supports the Lock View feature. This feature has several system * [`DATA_LOCK_WAITS`](/information-schema/information-schema-data-lock-waits.md): Provides the pessimistic lock-waiting information in TiKV, including the `start_ts` of the blocking and blocked transaction, the digest of the blocked SQL statement, and the key on which the waiting occurs. * [`DEADLOCKS` and `CLUSTER_DEADLOCKS`](/information-schema/information-schema-deadlocks.md): Provides the information of several deadlock events that have recently occurred on the current TiDB node or in the entire cluster, including the waiting relationship among transactions in the deadlock loops, the digest of the statement currently being executed in the transaction, and the key on which the waiting occurs. -> **Warning:** +> **Note:** > -> Currently, this is an experimental feature. The definition and behavior of the table structure might have major changes in future releases. +> The SQL statements shown in the Lock View-related system tables are normalized SQL statements (that is, SQL statements without format and parameters), which are obtained by SQL digest internal query, so the tables cannot obtain the complete statements that include the format and parameters. For the detailed description of SQL digests and normalized SQL statement, see [Statement Summary Tables](/statement-summary-tables.md). The following sections show the examples of troubleshooting some issues using these tables. @@ -258,32 +258,17 @@ select * from information_schema.deadlocks; ``` ```sql -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | KEY | TRX_HOLDING_LOCK | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904707 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000002 | 425405959304904708 | -| 1 | 2021-06-04 08:22:38.765699 | 0 | 425405959304904708 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | 7480000000000000385F728000000000000001 | 425405959304904707 | -+-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+----------------------------------------+--------------------+ ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| DEADLOCK_ID | OCCUR_TIME | RETRYABLE | TRY_LOCK_TRX_ID | CURRENT_SQL_DIGEST | CURRENT_SQL_DIGEST_TEXT | KEY | KEY_INFO | TRX_HOLDING_LOCK | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406216 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000002 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"2"} | 426812829645406217 | +| 1 | 2021-08-05 11:09:03.230341 | 0 | 426812829645406217 | 22230766411edb40f27a68dadefc63c6c6970d5827f1e5e22fc97be2c4d8350d | update `t` set `v` = ? where `id` = ? ; | 7480000000000000355F728000000000000001 | {"db_id":1,"db_name":"test","table_id":53,"table_name":"t","handle_type":"int","handle_value":"1"} | 426812829645406216 | ++-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -The query result above shows the waiting relationship among multiple transactions in the deadlock error, the digest of the SQL statement currently being executed in each transaction, and the key on which the conflict occurs. +The query result above shows the waiting relationship among multiple transactions in the deadlock error, the normalized form of the SQL statements currently being executed in each transaction (statements without format and parameters), the key on which the conflict occurs, and the information of the key. -You can get the text of the normalized SQL statement corresponding to the digest of the SQL statements executed recently from the `STATEMENTS_SUMMARY` or `STATEMENTS_SUMMARY_HISTORY` table. For details, see [`STATEMENTS_SUMMARY` and `STATEMENTS_SUMMARY_HISTORY` tables](/statement-summary-tables.md). You can also join the obtained results directly with the `DEADLOCKS` table. Note that the `STATEMENTS_SUMMARY` table might not contain the information of all SQL statements, so left join is used in the following example: - -{{< copyable "sql" >}} - -```sql -select l.deadlock_id, l.occur_time, l.try_lock_trx_id, l.trx_holding_lock, s.digest_text from information_schema.deadlocks as l left join information_schema.statements_summary as s on l.current_sql_digest = s.digest; -``` - -```sql -+-------------+----------------------------+--------------------+--------------------+-----------------------------------------+ -| deadlock_id | occur_time | try_lock_trx_id | trx_holding_lock | digest_text | -+-------------+----------------------------+--------------------+--------------------+-----------------------------------------+ -| 1 | 2021-06-04 08:22:38.765699 | 425405959304904707 | 425405959304904708 | update `t` set `v` = ? where `id` = ? ; | -| 1 | 2021-06-04 08:22:38.765699 | 425405959304904708 | 425405959304904707 | update `t` set `v` = ? where `id` = ? ; | -+-------------+----------------------------+--------------------+--------------------+-----------------------------------------+ -``` +For example, in the above example, the first row means that the transaction with the ID of `426812829645406216` is executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by another transaction with the ID of `426812829645406217`. The transaction with the ID of `426812829645406217` is also executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by the transaction with the ID of `426812829645406216`. The two transactions thus form a deadlock. #### A few hot keys cause queueing locks @@ -299,8 +284,8 @@ select `key`, count(*) as `count` from information_schema.data_lock_waits group +----------------------------------------+-------+ | key | count | +----------------------------------------+-------+ -| 7480000000000000415f728000000000000001 | 2 | -| 7480000000000000415f728000000000000002 | 1 | +| 7480000000000000415F728000000000000001 | 2 | +| 7480000000000000415F728000000000000002 | 1 | +----------------------------------------+-------+ ``` @@ -313,36 +298,36 @@ Note that the information displayed in the `TIDB_TRX` and `CLUSTER_TIDB_TRX` tab {{< copyable "sql" >}} ```sql -select trx.* from information_schema.data_lock_waits as l left join information_schema.tidb_trx as trx on l.trx_id = trx.id where l.key = "7480000000000000415f728000000000000001"\G +select trx.* from information_schema.data_lock_waits as l left join information_schema.tidb_trx as trx on l.trx_id = trx.id where l.key = "7480000000000000415F728000000000000001"\G ``` ```sql *************************** 1. row *************************** - ID: 425496938634543111 - START_TIME: 2021-06-08 08:46:48.341000 -CURRENT_SQL_DIGEST: a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9 - STATE: LockWaiting -WAITING_START_TIME: 2021-06-08 08:46:48.388024 - MEM_BUFFER_KEYS: 1 - MEM_BUFFER_BYTES: 19 - SESSION_ID: 87 - USER: root - DB: test - ALL_SQL_DIGESTS: [0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3, a4e28cc182bdd18288e2a34180499b9404cd0 -ba07e3cc34b6b3be7b7c2de7fe9, a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9] + ID: 426831815660273668 + START_TIME: 2021-08-06 07:16:00.081000 + CURRENT_SQL_DIGEST: 06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7 +CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? ; + STATE: LockWaiting + WAITING_START_TIME: 2021-08-06 07:16:00.087720 + MEM_BUFFER_KEYS: 0 + MEM_BUFFER_BYTES: 0 + SESSION_ID: 77 + USER: root + DB: test + ALL_SQL_DIGESTS: ["0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3","06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7"] *************************** 2. row *************************** - ID: 425496940994101249 - START_TIME: 2021-06-08 08:46:57.342000 -CURRENT_SQL_DIGEST: a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9 - STATE: LockWaiting -WAITING_START_TIME: 2021-06-08 08:46:57.590060 - MEM_BUFFER_KEYS: 0 - MEM_BUFFER_BYTES: 0 - SESSION_ID: 85 - USER: root - DB: test - ALL_SQL_DIGESTS: [0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3, a4e28cc182bdd18288e2a34180499b9404cd0 -ba07e3cc34b6b3be7b7c2de7fe9] + ID: 426831818019569665 + START_TIME: 2021-08-06 07:16:09.081000 + CURRENT_SQL_DIGEST: 06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7 +CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? ; + STATE: LockWaiting + WAITING_START_TIME: 2021-08-06 07:16:09.290271 + MEM_BUFFER_KEYS: 0 + MEM_BUFFER_BYTES: 0 + SESSION_ID: 75 + USER: root + DB: test + ALL_SQL_DIGESTS: ["0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3","06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7"] 2 rows in set (0.00 sec) ``` @@ -353,25 +338,29 @@ If a transaction is known to be blocked by another transaction (or multiple tran {{< copyable "sql" >}} ```sql -select l.key, trx.* from information_schema.data_lock_waits as l join information_schema.tidb_trx as trx on l.current_holding_trx_id = trx.id where l.trx_id = 425497223886536705\G +select l.key, trx.*, tidb_decode_sql_digests(trx.all_sql_digests) as sqls from information_schema.data_lock_waits as l join information_schema.cluster_tidb_trx as trx on l.current_holding_trx_id = trx.id where l.trx_id = 426831965449355272\G ``` ```sql *************************** 1. row *************************** - key: 7480000000000000475f728000000000000002 - ID: 425497219115778059 - START_TIME: 2021-06-08 09:04:38.292000 -CURRENT_SQL_DIGEST: a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9 - STATE: LockWaiting -WAITING_START_TIME: 2021-06-08 09:04:38.336264 - MEM_BUFFER_KEYS: 1 - MEM_BUFFER_BYTES: 19 - SESSION_ID: 97 - USER: root - DB: test - ALL_SQL_DIGESTS: [0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3, a4e28cc182bdd18288e2a34180499b9404cd0 -ba07e3cc34b6b3be7b7c2de7fe9, a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9] + key: 74800000000000004D5F728000000000000001 + INSTANCE: 127.0.0.1:10080 + ID: 426832040186609668 + START_TIME: 2021-08-06 07:30:16.581000 + CURRENT_SQL_DIGEST: 06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7 +CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? ; + STATE: LockWaiting + WAITING_START_TIME: 2021-08-06 07:30:16.592763 + MEM_BUFFER_KEYS: 1 + MEM_BUFFER_BYTES: 19 + SESSION_ID: 113 + USER: root + DB: test + ALL_SQL_DIGESTS: ["0fdc781f19da1c6078c9de7eadef8a307889c001e05f107847bee4cfc8f3cdf3","a4e28cc182bdd18288e2a34180499b9404cd0ba07e3cc34b6b3be7b7c2de7fe9","06da614b93e62713bd282d4685fc5b88d688337f36e88fe55871726ce0eb80d7"] + sqls: ["begin ;","select * from `t` where `id` = ? for update ;","update `t` set `v` = `v` + ? where `id` = ? ;"] 1 row in set (0.01 sec) ``` +In the above query, the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function is used on the `ALL_SQL_DIGESTS` column of the `CLUSTER_TIDB_TRX` table. This function tries to convert this column (the value is a set of SQL digests) to the normalized SQL statement, which improves readability. + If the `start_ts` of the current transaction is unknown, you can try to find it out from the information in the `TIDB_TRX` / `CLUSTER_TIDB_TRX` table or in the [`PROCESSLIST` / `CLUSTER_PROCESSLIST`](/information-schema/information-schema-processlist.md) table. From 0d90f2ec08fcc192106ccc9d5dac4d89b6f3671c Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Tue, 17 Aug 2021 14:22:23 +0800 Subject: [PATCH 02/11] Update information-schema/information-schema-tidb-trx.md --- information-schema/information-schema-tidb-trx.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index b683831cf3c6c..baa576621bf7e 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -98,7 +98,7 @@ CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? 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 similar to ``"update `t` set `v` = `v` +? where `id` = ?"``. where `id` = ?"``。 +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 similar to ``"update `t` set `v` = `v` +? where `id` = ?"``. where `id` = ?"``. {{< copyable "sql" >}} From f4972585302d99e2e7576f72f1bf4fbf01b4e0a7 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Tue, 17 Aug 2021 14:24:45 +0800 Subject: [PATCH 03/11] fix typo --- functions-and-operators/tidb-functions.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 82b93f0b7153b..9f3cf4743b59b 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -265,7 +265,7 @@ The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL state * `digests`: The string type, this parameter should conform to the format of a JSON string array, and each string in the array should be a SQL Digest. * `stmtTruncateLength`: Optional parameter, integer type, used to limit the length of each SQL statement in the returned result, and it will be truncated if it exceeds the specified length. 0 means unlimited length. -This function returns a string, which is in the format of a JSON string array. The *i* item in the array is the statement corresponding to the *i* element in the `digests` parameter. If an item in the digests` parameter `is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. +This function returns a string, which is in the format of a JSON string array. The *i* item in the array is the statement corresponding to the *i* element in the `digests` parameter. If an item in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. > **Note:** > From 401b38ac93fb725316999f168b24b36d70957326 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Wed, 18 Aug 2021 12:17:45 +0800 Subject: [PATCH 04/11] add a missing para by aligning #6882 --- information-schema/information-schema-tidb-trx.md | 2 ++ 1 file changed, 2 insertions(+) diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index baa576621bf7e..d008b9f85ce5a 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -117,6 +117,8 @@ all_sql_digests: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02 all_sqls: ["begin","update `t` set `v` = `v` + ? where `id` = ?"] ``` +This query calls the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#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's 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 contains 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 node where the transaction is located. From 6a240ae1308b5ffda17343e4e6bab07d2c403354 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Wed, 18 Aug 2021 13:58:23 +0800 Subject: [PATCH 05/11] Apply suggestions from code review Co-authored-by: MyonKeminta <9948422+MyonKeminta@users.noreply.github.com> --- functions-and-operators/tidb-functions.md | 14 +++++++------- .../information-schema-data-lock-waits.md | 10 +++++----- information-schema/information-schema-deadlocks.md | 13 +++++-------- information-schema/information-schema-tidb-trx.md | 10 +++++----- troubleshoot-lock-conflicts.md | 8 ++++---- 5 files changed, 26 insertions(+), 29 deletions(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 9f3cf4743b59b..51e778d0c6274 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -260,19 +260,19 @@ The `TIDB_VERSION` function is TiDB-specific and not compatible with MySQL. If M ## TIDB_DECODE_SQL_DIGESTS -The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL statements (a form without format and parameter) corresponding to the set of SQL digests in the cluster. This function accepts 1 or 2 parameters: +The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL statements (a form without format and arguments) corresponding to the set of SQL digests in the cluster. This function accepts 1 or 2 arguments: -* `digests`: The string type, this parameter should conform to the format of a JSON string array, and each string in the array should be a SQL Digest. -* `stmtTruncateLength`: Optional parameter, integer type, used to limit the length of each SQL statement in the returned result, and it will be truncated if it exceeds the specified length. 0 means unlimited length. +* `digests`: The string type. This parameter is in the format of a JSON string array, and each string in the array is a SQL digest. +* `stmtTruncateLength`: An Optional parameter and the integer type. It is used to limit the length of each SQL statement in the returned result. If a SQL statement exceeds the specified length, the statement is truncated. `0` means that the length is unlimited. -This function returns a string, which is in the format of a JSON string array. The *i* item in the array is the statement corresponding to the *i* element in the `digests` parameter. If an item in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. +This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the statement corresponding to the *i*-th element in the `digests` parameter. If an item in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. > **Note:** > -> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can use this function. -> * When `TIDB_DECODE_SQL_DIGESTS` is executed, TiDB queries the statement corresponding to each SQL digest from the series of statement summary tables, so there is no guarantee that the corresponding statement can always be queried for any SQL digest. Only the statements executed in the cluster might be queried, and whether these SQL statements can be queried or not is affected by the related configuration of the statement summary table. For the detailed description of the statement summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can use this function. +> * When `TIDB_DECODE_SQL_DIGESTS` is executed, TiDB queries the statement corresponding to each SQL digest from the statement summary tables, so there is no guarantee that the corresponding statement can always be found for any SQL digest. Only the statements that have been executed in the cluster can be found, and whether these SQL statements can be queried or not is also affected by the related configuration of the statement summary tables. For the detailed description of the statement summary table, see [Statement Summary Tables](/statement-summary-tables.md). > * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), directly using this function might cause the query to run longer time. Use it with caution. -> * This function has a high overhead because every time it is called, it internally queries the tables `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY` and, `CLUSTER_STATEMENTS_SUMMARY_HISTORY`, which also involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. +> * This function has a high overhead because every time it is called, it internally queries the tables `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY` and, `CLUSTER_STATEMENTS_SUMMARY_HISTORY`, and the query involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. ### Synopsis diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index 33a471f2005d3..a473281123935 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -34,14 +34,14 @@ The meaning of each column field in the `DATA_LOCK_WAITS` table is as follows: * `TRX_ID`: The ID of the transaction that is waiting for the lock. This ID is also the `start_ts` of the transaction. * `CURRENT_HOLDING_TRX_ID`: The ID of the transaction that currently holds the lock. This ID is also the `start_ts` of the transaction. * `SQL_DIGEST`: The digest of the SQL statement that is currently blocked in the lock-waiting transaction. -* `SQL_DIGEST_TEXT`: The normalized SQL statement (the SQL statement without parameters and format) that is currently blocked in the lock-waiting transaction. It corresponds to `SQL_DIGEST`. +* `SQL_DIGEST_TEXT`: The normalized SQL statement (the SQL statement without arguments and format) that is currently blocked in the lock-waiting transaction. It corresponds to `SQL_DIGEST`. > **Warning:** > -> * Only the users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can query this table. +> * Only the users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can query this table. > * The information in the `DATA_LOCK_WAITS` table is obtained in real time from all TiKV nodes during the query. Currently, even if a query has the `WHERE` condition, the information collection is still performed on all TiKV nodes. If your cluster is large and the load is high, querying this table might cause potential risk of performance jitter. Therefore, use it according to your actual situation. -> * Information from different TiKV nodes is not necessarily in snapshots of the same point in time. -> * The information (SQL digest) in the `SQL_DIGEST` column is the hash value calculated after the SQL statement is normalized. The information in the `SQL_DIGEST_TEXT` column is internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * Information from different TiKV nodes is NOT guaranteed to be in snapshots of the same point in time. +> * The information (SQL digest) in the `SQL_DIGEST` column is the hash value calculated from the normalized SQL statement. The information in the `SQL_DIGEST_TEXT` column is internally queried from 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](/statement-summary-tables.md). ## `KEY_INFO` @@ -62,7 +62,7 @@ The `KEY_INFO` column shows the detailed information of the key in the `KEY` col * `"index_name"`: The name of the index to which the index key belongs. * `"index_values"`: The index value in the index key. -In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information from `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. +In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. > **Note:** > diff --git a/information-schema/information-schema-deadlocks.md b/information-schema/information-schema-deadlocks.md index b636da617cd59..31f6cdbad4330 100644 --- a/information-schema/information-schema-deadlocks.md +++ b/information-schema/information-schema-deadlocks.md @@ -15,9 +15,6 @@ DESC deadlocks; ``` ```sql -+--------------------+---------------------+------+------+---------+-------+ -| Field | Type | Null | Key | Default | Extra | -+--------------------+---------------------+------+------+---------+-------+ +-------------------------+---------------------+------+------+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------------------------+---------------------+------+------+---------+-------+ @@ -42,7 +39,7 @@ The meaning of each column field in the `DEADLOCKS` table is as follows: * `RETRYABLE`: Whether the deadlock error can be retried. For the description of retryable deadlock errors, see the [Retryable deadlock errors](#retryable-deadlock-errors) section. * `TRY_LOCK_TRX_ID`: The ID of the transaction that tries to acquire lock. This ID is also the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the lock-acquiring transaction. -* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed in the lock-adding transaction. +* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed in the lock-acquiring transaction. * `KEY`: The blocked key that the transaction tries to lock. The value of this field is displayed in the form of hexadecimal string. * `KEY_INFO`: The detailed information of `KEY`. See the [KEY_INFO](#key_info) section. * `TRX_HOLDING_LOCK`: The ID of the transaction that currently holds the lock on the key and causes blocking. This ID is also the `start_ts` of the transaction. @@ -51,8 +48,8 @@ To adjust the maximum number of deadlock events that can be recorded in the `DEA > **Warning:** > -> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can query this table. -> * The information (SQL digest) in the `CURRENT_SQL_DIGEST` column is the hash value calculated after the SQL statement is normalized. The information in the `CURRENT_SQL_DIGEST_TEXT` column is internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can query this table. +> * The information (SQL digest) in the `CURRENT_SQL_DIGEST` column is the hash value calculated from the normalized SQL statement. The information in the `CURRENT_SQL_DIGEST_TEXT` column is internally queried from 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](/statement-summary-tables.md). ## `KEY_INFO` @@ -73,7 +70,7 @@ The `KEY_INFO` column shows the detailed information of the key in the `KEY` col * `"index_name"`: The name of the index to which the index key belongs. * `"index_values"`: The index value in the index key. -In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information from `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. +In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. > **Note:** > @@ -159,7 +156,7 @@ The expected output is as follows: +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that the transaction of the ID `425405959304904707` is blocked on the key of `"7480000000000000385F728000000000000002"` by the transaction of the ID `"425405959304904708"`. The second row shows that the transaction of the ID `"425405959304904708"` is blocked on the key of `"7480000000000000385F728000000000000001"` by the transaction of the ID `425405959304904707`, which constitutes mutual blocking and forms a deadlock. +Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that the transaction of the ID `426812829645406216` is blocked on the key of `"7480000000000000355F728000000000000002"` by the transaction of the ID `"426812829645406217"`. The second row shows that the transaction of the ID `"426812829645406217"` is blocked on the key of `"7480000000000000355F728000000000000001"` by the transaction of the ID `426812829645406216`, which constitutes mutual blocking and forms a deadlock. ## Example 2 diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index d008b9f85ce5a..743bbdb287203 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -38,7 +38,7 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: * `ID`: The transaction ID, which is the `start_ts` (start timestamp) of the transaction. * `START_TIME`: The start time of the transaction, which is the physical time corresponding to the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the transaction. -* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed by the transaction, that is, the SQL statement without parameters and format. It corresponds to `CURRENT_SQL_DIGEST`. +* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed by the transaction, that is, the SQL statement without arguments and format. It corresponds to `CURRENT_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. @@ -55,10 +55,10 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: > **Note:** > -> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) permission can obtain the complete information in this table. Users without the PROCESS permission can only query information of the transactions performed by the current user. -> * The information (SQL digest) in the `CURRENT_SQL_DIGEST` and `ALL_SQL_DIGESTS` columns is the hash value calculated after the SQL statement is normalized. The information in the `CURRENT_SQL_DIGEST_TEXT` column and the result returned from the `TIDB_DECODE_SQL_DIGESTS` function are internally queried from the series of statements summary tables, so the corresponding statement might not be queried internally. For the detailed description of SQL digests and the statements summary table, see [Statement Summary Tables](/statement-summary-tables.md). +> * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_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_DIGEST` and `ALL_SQL_DIGESTS` columns is the hash value calculated from the normalized SQL statement. The information in the `CURRENT_SQL_DIGEST_TEXT` column and the result returned from the `TIDB_DECODE_SQL_DIGESTS` function 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](/statement-summary-tables.md). > * The [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function 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 the `ALL_SQL_DIGEST` column while querying the full table of `TIDB_TRX`. This means to avoid SQL statement like ``select *, tidb_decode_sql_digests(all_sql_digests) from tidb_trx``. -> * Currently the `TIDB_TRX` table does not support showing information related to TiDB transactions. +> * Currently the `TIDB_TRX` table does not support showing information of TiDB's internal transactions. ## Example @@ -98,7 +98,7 @@ CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? 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 similar to ``"update `t` set `v` = `v` +? where `id` = ?"``. where `id` = ?"``. +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` = ?"``. where `id` = ?"``. {{< copyable "sql" >}} diff --git a/troubleshoot-lock-conflicts.md b/troubleshoot-lock-conflicts.md index 36cd5d3427e42..fae9f2da81841 100644 --- a/troubleshoot-lock-conflicts.md +++ b/troubleshoot-lock-conflicts.md @@ -243,7 +243,7 @@ Since v5.1, TiDB supports the Lock View feature. This feature has several system > **Note:** > -> The SQL statements shown in the Lock View-related system tables are normalized SQL statements (that is, SQL statements without format and parameters), which are obtained by SQL digest internal query, so the tables cannot obtain the complete statements that include the format and parameters. For the detailed description of SQL digests and normalized SQL statement, see [Statement Summary Tables](/statement-summary-tables.md). +> The SQL statements shown in the Lock View-related system tables are normalized SQL statements (that is, SQL statements without format and arguments), which are obtained by internal queries according to SQL digests, so the tables cannot obtain the complete statements that include the format and arguments. For the detailed description of SQL digests and normalized SQL statement, see [Statement Summary Tables](/statement-summary-tables.md). The following sections show the examples of troubleshooting some issues using these tables. @@ -266,9 +266,9 @@ select * from information_schema.deadlocks; +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -The query result above shows the waiting relationship among multiple transactions in the deadlock error, the normalized form of the SQL statements currently being executed in each transaction (statements without format and parameters), the key on which the conflict occurs, and the information of the key. +The query result above shows the waiting relationship among multiple transactions in the deadlock error, the normalized form of the SQL statements currently being executed in each transaction (statements without format and arguments), the key on which the conflict occurs, and the information of the key. -For example, in the above example, the first row means that the transaction with the ID of `426812829645406216` is executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by another transaction with the ID of `426812829645406217`. The transaction with the ID of `426812829645406217` is also executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by the transaction with the ID of `426812829645406216`. The two transactions thus form a deadlock. +For example, in the above example, the first row means that the transaction with the ID of `426812829645406216` is executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by another transaction with the ID of `426812829645406217`. The transaction with the ID of `426812829645406217` is also executing a statement that is in the form of ``update `t` set `v` =? Where `id` =? ;`` but is blocked by the transaction with the ID of `426812829645406216`. The two transactions thus form a deadlock. #### A few hot keys cause queueing locks @@ -361,6 +361,6 @@ CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? ; 1 row in set (0.01 sec) ``` -In the above query, the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function is used on the `ALL_SQL_DIGESTS` column of the `CLUSTER_TIDB_TRX` table. This function tries to convert this column (the value is a set of SQL digests) to the normalized SQL statement, which improves readability. +In the above query, the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function is used on the `ALL_SQL_DIGESTS` column of the `CLUSTER_TIDB_TRX` table. This function tries to convert this column (the value is a set of SQL digests) to the normalized SQL statements, which improves readability. If the `start_ts` of the current transaction is unknown, you can try to find it out from the information in the `TIDB_TRX` / `CLUSTER_TIDB_TRX` table or in the [`PROCESSLIST` / `CLUSTER_PROCESSLIST`](/information-schema/information-schema-processlist.md) table. From 888f6f0f29c367f5dfc7efc98302f860cbc01b9d Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Wed, 18 Aug 2021 14:54:15 +0800 Subject: [PATCH 06/11] Update functions-and-operators/tidb-functions.md Co-authored-by: MyonKeminta <9948422+MyonKeminta@users.noreply.github.com> --- functions-and-operators/tidb-functions.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 51e778d0c6274..4a65d4fa984a7 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -271,7 +271,7 @@ This function returns a string, which is in the format of a JSON string array. T > > * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can use this function. > * When `TIDB_DECODE_SQL_DIGESTS` is executed, TiDB queries the statement corresponding to each SQL digest from the statement summary tables, so there is no guarantee that the corresponding statement can always be found for any SQL digest. Only the statements that have been executed in the cluster can be found, and whether these SQL statements can be queried or not is also affected by the related configuration of the statement summary tables. For the detailed description of the statement summary table, see [Statement Summary Tables](/statement-summary-tables.md). -> * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), directly using this function might cause the query to run longer time. Use it with caution. +> * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), directly using this function might cause the query to run for too long. Use it with caution. > * This function has a high overhead because every time it is called, it internally queries the tables `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY` and, `CLUSTER_STATEMENTS_SUMMARY_HISTORY`, and the query involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. ### Synopsis From d4557703c5fc95ddb266395659898ad2db2c71bf Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Wed, 18 Aug 2021 15:00:03 +0800 Subject: [PATCH 07/11] Update information-schema/information-schema-data-lock-waits.md --- information-schema/information-schema-data-lock-waits.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index a473281123935..6dcdaea13ac04 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -87,4 +87,4 @@ CURRENT_HOLDING_TRX_ID: 426790590082449409 1 row in set (0.01 sec) ``` -The above query result shows that the transaction of the ID `425405024158875649` was trying to obtain the pessimistic lock on the key `7480000000000000355f728000000000000002` when the statement with digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` was being executed, but the lock on this key was held by the transaction of the ID `425405016242126849`. +The above query result shows that the transaction of the ID `425405024158875649` was trying to obtain the pessimistic lock on the key `7480000000000000355f728000000000000002` when the statement like ``update `t` set `v` = `v` + ? where `id` = ?`` with the digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` was being executed, but the lock on this key was held by the transaction of the ID `425405016242126849`. From 0add32abc93c016f18ce9d9f4c63e6df1db82591 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Fri, 20 Aug 2021 16:01:53 +0800 Subject: [PATCH 08/11] Apply suggestions from code review Co-authored-by: Grace Cai Co-authored-by: MyonKeminta <9948422+MyonKeminta@users.noreply.github.com> --- functions-and-operators/tidb-functions.md | 14 +++++------ .../information-schema-data-lock-waits.md | 22 ++++++++--------- .../information-schema-deadlocks.md | 24 +++++++++---------- .../information-schema-tidb-trx.md | 10 ++++---- troubleshoot-lock-conflicts.md | 4 ++-- 5 files changed, 37 insertions(+), 37 deletions(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 4a65d4fa984a7..2359dacc1d48b 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -260,19 +260,19 @@ The `TIDB_VERSION` function is TiDB-specific and not compatible with MySQL. If M ## TIDB_DECODE_SQL_DIGESTS -The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL statements (a form without format and arguments) corresponding to the set of SQL digests in the cluster. This function accepts 1 or 2 arguments: +The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL statements (a form without formats and arguments) corresponding to the set of SQL digests in the cluster. This function accepts 1 or 2 arguments: -* `digests`: The string type. This parameter is in the format of a JSON string array, and each string in the array is a SQL digest. -* `stmtTruncateLength`: An Optional parameter and the integer type. It is used to limit the length of each SQL statement in the returned result. If a SQL statement exceeds the specified length, the statement is truncated. `0` means that the length is unlimited. +* `digests`: A string. This parameter is in the format of a JSON string array, and each string in the array is a SQL digest. +* `stmtTruncateLength`: An integer (optional). It is used to limit the length of each SQL statement in the returned result. If a SQL statement exceeds the specified length, the statement is truncated. `0` means that the length is unlimited. -This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the statement corresponding to the *i*-th element in the `digests` parameter. If an item in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength> 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate that truncation has occurred. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. +This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the normalized SQL statement corresponding to the *i*-th element in the `digests` parameter. If an element in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength > 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate the truncation. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. > **Note:** > > * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can use this function. > * When `TIDB_DECODE_SQL_DIGESTS` is executed, TiDB queries the statement corresponding to each SQL digest from the statement summary tables, so there is no guarantee that the corresponding statement can always be found for any SQL digest. Only the statements that have been executed in the cluster can be found, and whether these SQL statements can be queried or not is also affected by the related configuration of the statement summary tables. For the detailed description of the statement summary table, see [Statement Summary Tables](/statement-summary-tables.md). -> * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), directly using this function might cause the query to run for too long. Use it with caution. -> * This function has a high overhead because every time it is called, it internally queries the tables `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY` and, `CLUSTER_STATEMENTS_SUMMARY_HISTORY`, and the query involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. +> * This function has a high overhead. In queries with a large number of rows (for example, querying the full table of `information_schema.cluster_tidb_trx` on a large and busy cluster), using this function might cause the queries to run for too long. Use it with caution. +> * This function has a high overhead because every time it is called, it internally queries the `STATEMENTS_SUMMARY`, `STATEMENTS_SUMMARY_HISTORY`, `CLUSTER_STATEMENTS_SUMMARY`, and `CLUSTER_STATEMENTS_SUMMARY_HISTORY` tables, and the query involves the `UNION` operation. This function currently does not support vectorization, that is, when calling this function for multiple rows of data, the above query is performed separately for each row. ### Synopsis @@ -317,7 +317,7 @@ select tidb_decode_sql_digests(@digests, 10); 1 row in set (0.01 sec) ``` -The above call specifies the second parameter (that is, the truncation length) as 10, and the length of the third statement in the query result is greater than 10. Therefore, only the first 10 characters are retained and `"..." is added at the end, which indicates that truncation has occurred. +The above call specifies the second parameter (that is, the truncation length) as 10, and the length of the third statement in the query result is greater than 10. Therefore, only the first 10 characters are retained, and `"..."` is added at the end, which indicates the truncation. ### MySQL compatibility diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index 6dcdaea13ac04..7327243340d56 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -29,23 +29,23 @@ DESC data_lock_waits; The meaning of each column field in the `DATA_LOCK_WAITS` table is as follows: -* `KEY`: The key that is waiting for the lock and displayed in the form of hexadecimal string. +* `KEY`: The key that is waiting for the lock and in the hexadecimal form. * `KEY_INFO`: The detailed information of `KEY`. See the [KEY_INFO](#key_info) section. * `TRX_ID`: The ID of the transaction that is waiting for the lock. This ID is also the `start_ts` of the transaction. * `CURRENT_HOLDING_TRX_ID`: The ID of the transaction that currently holds the lock. This ID is also the `start_ts` of the transaction. * `SQL_DIGEST`: The digest of the SQL statement that is currently blocked in the lock-waiting transaction. -* `SQL_DIGEST_TEXT`: The normalized SQL statement (the SQL statement without arguments and format) that is currently blocked in the lock-waiting transaction. It corresponds to `SQL_DIGEST`. +* `SQL_DIGEST_TEXT`: The normalized SQL statement (the SQL statement without arguments and formats) that is currently blocked in the lock-waiting transaction. It corresponds to `SQL_DIGEST`. > **Warning:** > > * Only the users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_process) privilege can query this table. > * The information in the `DATA_LOCK_WAITS` table is obtained in real time from all TiKV nodes during the query. Currently, even if a query has the `WHERE` condition, the information collection is still performed on all TiKV nodes. If your cluster is large and the load is high, querying this table might cause potential risk of performance jitter. Therefore, use it according to your actual situation. -> * Information from different TiKV nodes is NOT guaranteed to be in snapshots of the same point in time. +> * Information from different TiKV nodes is NOT guaranteed to be snapshots of the same time. > * The information (SQL digest) in the `SQL_DIGEST` column is the hash value calculated from the normalized SQL statement. The information in the `SQL_DIGEST_TEXT` column is internally queried from 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](/statement-summary-tables.md). ## `KEY_INFO` -The `KEY_INFO` column shows the detailed information of the key in the `KEY` column. The information is shown in the JSON format. The contained fields are described as follows: +The `KEY_INFO` column shows the detailed information of the `KEY` column. The information is shown in the JSON format. The description of each field is as follows: * `"db_id"`: The ID of the schema to which the key belongs. * `"db_name"`: The name of the schema to which the key belongs. @@ -53,20 +53,20 @@ The `KEY_INFO` column shows the detailed information of the key in the `KEY` col * `"table_name"`: The name of the table to which the key belongs. * `"partition_id"`: The ID of the partition where the key is located. * `"partition_name"`: The name of the partition where the key is located. -* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). Its possible values ​​are as follows: - * `"int"`: The handle is of the int type, which means that the handle is the row ID. - * `"common"`: The handle of the non-int64 type. This type is shown in the non-int primary key when clustered index is enabled. - * `"unknown"`: The handle type that is currently not supported. +* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). The possible values ​​are as follows: + * `"int"`: The handle type is int, which means that the handle is the row ID. + * `"common"`: The handle type is not int64. This type is shown in the non-int primary key when clustered index is enabled. + * `"unknown"`: The handle type is currently not supported. * `"handle_value"`: The handle value. * `"index_id"`: The index ID to which the index key (the key that stores the index) belongs. * `"index_name"`: The name of the index to which the index key belongs. * `"index_values"`: The index value in the index key. -In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. +In the above fields, if the information of a field is not applicable or currently unavailable, the field is omitted in the query result. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether the table is a partitioned table. > **Note:** > -> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one of a table partition. +> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one partition of a table. ## Example @@ -87,4 +87,4 @@ CURRENT_HOLDING_TRX_ID: 426790590082449409 1 row in set (0.01 sec) ``` -The above query result shows that the transaction of the ID `425405024158875649` was trying to obtain the pessimistic lock on the key `7480000000000000355f728000000000000002` when the statement like ``update `t` set `v` = `v` + ? where `id` = ?`` with the digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` was being executed, but the lock on this key was held by the transaction of the ID `425405016242126849`. +The above query result shows that the transaction of the ID `426790594290122753` is trying to obtain the pessimistic lock on the key `7480000000000000355F728000000000000001` when executing a statement that has digest `"38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821"` and is in the form of ``update `t` set `v` = `v` + ? where `id` = ?``, but the lock on this key was held by the transaction of the ID `426790590082449409`. diff --git a/information-schema/information-schema-deadlocks.md b/information-schema/information-schema-deadlocks.md index 31f6cdbad4330..dcddb0941ca7d 100644 --- a/information-schema/information-schema-deadlocks.md +++ b/information-schema/information-schema-deadlocks.md @@ -39,7 +39,7 @@ The meaning of each column field in the `DEADLOCKS` table is as follows: * `RETRYABLE`: Whether the deadlock error can be retried. For the description of retryable deadlock errors, see the [Retryable deadlock errors](#retryable-deadlock-errors) section. * `TRY_LOCK_TRX_ID`: The ID of the transaction that tries to acquire lock. This ID is also the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the lock-acquiring transaction. -* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed in the lock-acquiring transaction. +* `CURRENT_SQL_DIGEST_TEXT`: The normalized form of the SQL statement that is currently being executed in the lock-acquiring transaction. * `KEY`: The blocked key that the transaction tries to lock. The value of this field is displayed in the form of hexadecimal string. * `KEY_INFO`: The detailed information of `KEY`. See the [KEY_INFO](#key_info) section. * `TRX_HOLDING_LOCK`: The ID of the transaction that currently holds the lock on the key and causes blocking. This ID is also the `start_ts` of the transaction. @@ -53,7 +53,7 @@ To adjust the maximum number of deadlock events that can be recorded in the `DEA ## `KEY_INFO` -The `KEY_INFO` column shows the detailed information of the key in the `KEY` column. The information is shown in the JSON format. The contained fields are described as follows: +The `KEY_INFO` column shows the detailed information of the `KEY` column. The information is shown in the JSON format. The description of each field is as follows: * `"db_id"`: The ID of the schema to which the key belongs. * `"db_name"`: The name of the schema to which the key belongs. @@ -61,20 +61,20 @@ The `KEY_INFO` column shows the detailed information of the key in the `KEY` col * `"table_name"`: The name of the table to which the key belongs. * `"partition_id"`: The ID of the partition where the key is located. * `"partition_name"`: The name of the partition where the key is located. -* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). Its possible values ​​are as follows: - * `"int"`: The handle is of the int type, which means that the handle is the row ID. - * `"common"`: The handle of the non-int64 type. This type is shown in the non-int primary key when clustered index is enabled. - * `"unknown"`: The handle type that is currently not supported. +* `"handle_type"`: The handle type of the row key (that is, the key that stores a row of data). The possible values ​​are as follows: + * `"int"`: The handle type is int, which means that the handle is the row ID. + * `"common"`: The handle type is not int64. This type is shown in the non-int primary key when clustered index is enabled. + * `"unknown"`: The handle type is currently not supported. * `"handle_value"`: The handle value. * `"index_id"`: The index ID to which the index key (the key that stores the index) belongs. * `"index_name"`: The name of the index to which the index key belongs. * `"index_values"`: The index value in the index key. -In the above fields, if the information is not applicable or currently unavailable, it is omitted. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether it is a partitioned table. +In the above fields, if the information of a field is not applicable or currently unavailable, the field is omitted in the query result. For example, the row key information does not contain `index_id`, `index_name`, and `index_values`; the index key does not contain `handle_type` and `handle_value`; non-partitioned tables do not display `partition_id` and `partition_name`; the key information in the deleted table cannot obtain schema information such as `table_name`, `db_id`, `db_name`, and `index_name`, and it is unable to distinguish whether the table is a partitioned table. > **Note:** > -> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one of a table partition. +> If a key comes from a table with partitioning enabled, and the information of the schema to which the key belongs cannot be queried due to some reasons (for example, the table to which the key belongs has been deleted) during the query, the ID of the partition to which the key belongs might be appear in the `table_id` field. This is because TiDB encodes the keys of different partitions in the same way as it encodes the keys of several independent tables. Therefore, when the schema information is missing, TiDB cannot confirm whether the key belongs to an unpartitioned table or to one partition of a table. ## Retryable deadlock errors @@ -128,7 +128,7 @@ create table t (id int primary key, v int); insert into t values (1, 10), (2, 20); ``` -Execute the two transactions in the following order: +Two transactions are executed in the following order: | Transaction 1 | Transaction 2 | Description | |--------------------------------------|--------------------------------------|----------------------| @@ -156,7 +156,7 @@ The expected output is as follows: +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that the transaction of the ID `426812829645406216` is blocked on the key of `"7480000000000000355F728000000000000002"` by the transaction of the ID `"426812829645406217"`. The second row shows that the transaction of the ID `"426812829645406217"` is blocked on the key of `"7480000000000000355F728000000000000001"` by the transaction of the ID `426812829645406216`, which constitutes mutual blocking and forms a deadlock. +Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that on the key of `"7480000000000000355F728000000000000002"`, the transaction of the ID `426812829645406216` is blocked by the transaction of the ID `"426812829645406217"`. The second row shows that on the key of `"7480000000000000355F728000000000000001"`, the transaction of the ID `"426812829645406217"` is blocked by the transaction of the ID `426812829645406216`, which constitutes mutual blocking and forms a deadlock. ## Example 2 @@ -174,11 +174,11 @@ Assume that you query the `DEADLOCKS` table and get the following result: +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -The `DEADLOCK_ID` column in the above query result shows that the first two rows together represent the information of a deadlock error, and the two transactions that wait for each other form the deadlock. The next three rows together represent another deadlock information, and the three transactions that wait in a cycle form the deadlock. +The `DEADLOCK_ID` column in the above query result shows that the first two rows together represent the information of a deadlock error, and the two transactions that wait for each other form the deadlock. The next three rows together represent the information of another deadlock error, and the three transactions that wait in a cycle form the deadlock. ## CLUSTER_DEADLOCKS -The `CLUSTER_DEADLOCKS` table returns information about the recent deadlock errors on each TiDB node in the entire cluster, which is the information of the `DEADLOCKS` table on each node combined together. `CLUSTER_DEADLOCKS` also contains an additional `INSTANCE` column to display the IP address and port of the node to distinguish between different TiDB nodes. +The `CLUSTER_DEADLOCKS` table returns information about the recent deadlock errors on each TiDB node in the entire cluster, which is the combined information of the `DEADLOCKS` table on each node. `CLUSTER_DEADLOCKS` also includes an additional `INSTANCE` column to display the IP address and port of the node to distinguish between different TiDB nodes. Note that, because `DEADLOCK_ID` does not guarantee global uniqueness, in the query result of the `CLUSTER_DEADLOCKS` table, you need to use the `INSTANCE` and `DEADLOCK_ID` together to distinguish the information of different deadlock errors in the result set. diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index 743bbdb287203..874b1a31b51b5 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -38,7 +38,7 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: * `ID`: The transaction ID, which is the `start_ts` (start timestamp) of the transaction. * `START_TIME`: The start time of the transaction, which is the physical time corresponding to the `start_ts` of the transaction. * `CURRENT_SQL_DIGEST`: The digest of the SQL statement currently being executed in the transaction. -* `CURRENT_SQL_DIGEST_TEXT`: The normalized SQL statement currently being executed by the transaction, that is, the SQL statement without arguments and format. It corresponds to `CURRENT_SQL_DIGEST`. +* `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 to `CURRENT_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. @@ -57,8 +57,8 @@ The meaning of each column field in the `TIDB_TRX` table is as follows: > > * Only users with the [PROCESS](https://dev.mysql.com/doc/refman/8.0/en/privileges-provided.html#priv_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_DIGEST` and `ALL_SQL_DIGESTS` columns is the hash value calculated from the normalized SQL statement. The information in the `CURRENT_SQL_DIGEST_TEXT` column and the result returned from the `TIDB_DECODE_SQL_DIGESTS` function 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](/statement-summary-tables.md). -> * The [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function 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 the `ALL_SQL_DIGEST` column while querying the full table of `TIDB_TRX`. This means to avoid SQL statement like ``select *, tidb_decode_sql_digests(all_sql_digests) from tidb_trx``. -> * Currently the `TIDB_TRX` table does not support showing information of TiDB's internal transactions. +> * The [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#tidb_decode_sql_digests) function 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 the `ALL_SQL_DIGEST` column while querying the full table of `TIDB_TRX`. This means to avoid an SQL statement like ``select *, tidb_decode_sql_digests(all_sql_digests) from tidb_trx``. +> * Currently the `TIDB_TRX` table does not support showing information of TiDB internal transactions. ## Example @@ -117,11 +117,11 @@ all_sql_digests: ["e6f07d43b5c21db0fbb9a31feac2dc599787763393dd5acbfad80e247eb02 all_sqls: ["begin","update `t` set `v` = `v` + ? where `id` = ?"] ``` -This query calls the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#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's 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. +This query calls the [`TIDB_DECODE_SQL_DIGESTS`](/functions-and-operators/tidb-functions.md#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 contains 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 node where the transaction is located. +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. {{< copyable "sql" >}} diff --git a/troubleshoot-lock-conflicts.md b/troubleshoot-lock-conflicts.md index fae9f2da81841..eb3c31ff23f8c 100644 --- a/troubleshoot-lock-conflicts.md +++ b/troubleshoot-lock-conflicts.md @@ -243,7 +243,7 @@ Since v5.1, TiDB supports the Lock View feature. This feature has several system > **Note:** > -> The SQL statements shown in the Lock View-related system tables are normalized SQL statements (that is, SQL statements without format and arguments), which are obtained by internal queries according to SQL digests, so the tables cannot obtain the complete statements that include the format and arguments. For the detailed description of SQL digests and normalized SQL statement, see [Statement Summary Tables](/statement-summary-tables.md). +> The SQL statements shown in the Lock View-related system tables are normalized SQL statements (that is, SQL statements without formats and arguments), which are obtained by internal queries according to SQL digests, so the tables cannot obtain the complete statements that include the format and arguments. For the detailed description of SQL digests and normalized SQL statement, see [Statement Summary Tables](/statement-summary-tables.md). The following sections show the examples of troubleshooting some issues using these tables. @@ -266,7 +266,7 @@ select * from information_schema.deadlocks; +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -The query result above shows the waiting relationship among multiple transactions in the deadlock error, the normalized form of the SQL statements currently being executed in each transaction (statements without format and arguments), the key on which the conflict occurs, and the information of the key. +The query result above shows the waiting relationship among multiple transactions in the deadlock error, the normalized form of the SQL statements currently being executed in each transaction (statements without formats and arguments), the key on which the conflict occurs, and the information of the key. For example, in the above example, the first row means that the transaction with the ID of `426812829645406216` is executing a statement like ``update `t` set `v` =? Where `id` =? ;`` but is blocked by another transaction with the ID of `426812829645406217`. The transaction with the ID of `426812829645406217` is also executing a statement that is in the form of ``update `t` set `v` =? Where `id` =? ;`` but is blocked by the transaction with the ID of `426812829645406216`. The two transactions thus form a deadlock. From 88ba29ae037babf2e00e64c92de2bf303651c6e8 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Mon, 23 Aug 2021 14:16:51 +0800 Subject: [PATCH 09/11] Apply suggestions from code review --- functions-and-operators/tidb-functions.md | 2 +- information-schema/information-schema-data-lock-waits.md | 2 +- information-schema/information-schema-deadlocks.md | 2 +- information-schema/information-schema-tidb-trx.md | 2 +- 4 files changed, 4 insertions(+), 4 deletions(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index 2359dacc1d48b..ec838a5d26f11 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -265,7 +265,7 @@ The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL state * `digests`: A string. This parameter is in the format of a JSON string array, and each string in the array is a SQL digest. * `stmtTruncateLength`: An integer (optional). It is used to limit the length of each SQL statement in the returned result. If a SQL statement exceeds the specified length, the statement is truncated. `0` means that the length is unlimited. -This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the normalized SQL statement corresponding to the *i*-th element in the `digests` parameter. If an element in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength > 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate the truncation. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. +This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the normalized SQL statement corresponding to the *i*-th element in the `digests` parameter. If an element in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `NULL`. If the truncation length is specified (`stmtTruncateLength > 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate the truncation. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. > **Note:** > diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index 7327243340d56..19cee4e53c9f4 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -87,4 +87,4 @@ CURRENT_HOLDING_TRX_ID: 426790590082449409 1 row in set (0.01 sec) ``` -The above query result shows that the transaction of the ID `426790594290122753` is trying to obtain the pessimistic lock on the key `7480000000000000355F728000000000000001` when executing a statement that has digest `"38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821"` and is in the form of ``update `t` set `v` = `v` + ? where `id` = ?``, but the lock on this key was held by the transaction of the ID `426790590082449409`. +The above query result shows that the transaction of the ID `425405024158875649` is trying to obtain the pessimistic lock on the key `"7480000000000000355f728000000000000002"` when executing a statement that has digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` and is in the form of ``update `t` set `v` = `v` + ? where `id` = ?``, but the lock on this key was held by the transaction of the ID `425405016242126849`. diff --git a/information-schema/information-schema-deadlocks.md b/information-schema/information-schema-deadlocks.md index dcddb0941ca7d..67c377ff82ae5 100644 --- a/information-schema/information-schema-deadlocks.md +++ b/information-schema/information-schema-deadlocks.md @@ -156,7 +156,7 @@ The expected output is as follows: +-------------+----------------------------+-----------+--------------------+------------------------------------------------------------------+-----------------------------------------+----------------------------------------+----------------------------------------------------------------------------------------------------+--------------------+ ``` -Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that on the key of `"7480000000000000355F728000000000000002"`, the transaction of the ID `426812829645406216` is blocked by the transaction of the ID `"426812829645406217"`. The second row shows that on the key of `"7480000000000000355F728000000000000001"`, the transaction of the ID `"426812829645406217"` is blocked by the transaction of the ID `426812829645406216`, which constitutes mutual blocking and forms a deadlock. +Two rows of data are generated in the `DEADLOCKS` table. The `DEADLOCK_ID` field of both rows is `1`, which means that the information in both rows belongs to the same deadlock error. The first row shows that on the key of `"7480000000000000355F728000000000000002"`, the transaction of the ID `"426812829645406216"` is blocked by the transaction of the ID `"426812829645406217"`. The second row shows that on the key of `"7480000000000000355F728000000000000001"`, the transaction of the ID `"426812829645406217"` is blocked by the transaction of the ID `426812829645406216`, which constitutes mutual blocking and forms a deadlock. ## Example 2 diff --git a/information-schema/information-schema-tidb-trx.md b/information-schema/information-schema-tidb-trx.md index 874b1a31b51b5..f67d881eca3f4 100644 --- a/information-schema/information-schema-tidb-trx.md +++ b/information-schema/information-schema-tidb-trx.md @@ -98,7 +98,7 @@ CURRENT_SQL_DIGEST_TEXT: update `t` set `v` = `v` + ? where `id` = ? 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` = ?"``. where `id` = ?"``. +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` = ?"``. {{< copyable "sql" >}} From a2b9f65d8cae724a6e5f25caee48857c493e7594 Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Tue, 24 Aug 2021 19:01:08 +0800 Subject: [PATCH 10/11] Update functions-and-operators/tidb-functions.md --- functions-and-operators/tidb-functions.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/functions-and-operators/tidb-functions.md b/functions-and-operators/tidb-functions.md index ec838a5d26f11..2359dacc1d48b 100644 --- a/functions-and-operators/tidb-functions.md +++ b/functions-and-operators/tidb-functions.md @@ -265,7 +265,7 @@ The `TIDB_DECODE_SQL_DIGESTS` function is used to query the normalized SQL state * `digests`: A string. This parameter is in the format of a JSON string array, and each string in the array is a SQL digest. * `stmtTruncateLength`: An integer (optional). It is used to limit the length of each SQL statement in the returned result. If a SQL statement exceeds the specified length, the statement is truncated. `0` means that the length is unlimited. -This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the normalized SQL statement corresponding to the *i*-th element in the `digests` parameter. If an element in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `NULL`. If the truncation length is specified (`stmtTruncateLength > 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate the truncation. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. +This function returns a string, which is in the format of a JSON string array. The *i*-th item in the array is the normalized SQL statement corresponding to the *i*-th element in the `digests` parameter. If an element in the `digests` parameter is not a valid SQL digest or the system cannot find the corresponding SQL statement, the corresponding item in the returned result is `null`. If the truncation length is specified (`stmtTruncateLength > 0`), for each statement in the returned result that exceeds this length, the first `stmtTruncateLength` characters are retained and the suffix `"..."` is added at the end to indicate the truncation. If the `digests` parameter is `NULL`, the returned value of the function is `NULL`. > **Note:** > From 264e0b7bb5055e0633c316e91321f433b44d10fe Mon Sep 17 00:00:00 2001 From: TomShawn <41534398+TomShawn@users.noreply.github.com> Date: Tue, 24 Aug 2021 19:03:28 +0800 Subject: [PATCH 11/11] Update information-schema/information-schema-data-lock-waits.md --- information-schema/information-schema-data-lock-waits.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/information-schema/information-schema-data-lock-waits.md b/information-schema/information-schema-data-lock-waits.md index 19cee4e53c9f4..37051b0d89704 100644 --- a/information-schema/information-schema-data-lock-waits.md +++ b/information-schema/information-schema-data-lock-waits.md @@ -87,4 +87,4 @@ CURRENT_HOLDING_TRX_ID: 426790590082449409 1 row in set (0.01 sec) ``` -The above query result shows that the transaction of the ID `425405024158875649` is trying to obtain the pessimistic lock on the key `"7480000000000000355f728000000000000002"` when executing a statement that has digest `"f7530877a35ae65300c42250abd8bc731bbaf0a7cabc05dab843565230611bb22"` and is in the form of ``update `t` set `v` = `v` + ? where `id` = ?``, but the lock on this key was held by the transaction of the ID `425405016242126849`. +The above query result shows that the transaction of the ID `426790594290122753` is trying to obtain the pessimistic lock on the key `"7480000000000000355F728000000000000001"` when executing a statement that has digest `"38b03afa5debbdf0326a014dbe5012a62c51957f1982b3093e748460f8b00821"` and is in the form of ``update `t` set `v` = `v` + ? where `id` = ?``, but the lock on this key was held by the transaction of the ID `426790590082449409`.