From 1772e6d1357d1b1d45fcf104302186b91d262dd8 Mon Sep 17 00:00:00 2001 From: qw4990 Date: Thu, 14 Mar 2024 18:38:44 +0800 Subject: [PATCH 01/13] fixup --- optimizer-hints.md | 2 +- sql-plan-management.md | 46 ++++++++++++++++++++++++++++++++++++++++++ system-variables.md | 10 +++++++++ 3 files changed, 57 insertions(+), 1 deletion(-) diff --git a/optimizer-hints.md b/optimizer-hints.md index 38a7813cf4ced..369020b628aae 100644 --- a/optimizer-hints.md +++ b/optimizer-hints.md @@ -12,7 +12,7 @@ If you encounter a situation where hints do not take effect, see [Troubleshoot c ## Syntax -Optimizer hints are case insensitive and specified within `/*+ ... */` comments following the `SELECT`, `UPDATE` or `DELETE` keyword in a SQL statement. Optimizer hints are not currently supported for `INSERT` statements. +Optimizer hints are case insensitive and specified within `/*+ ... */` comments following the `SELECT`, `INSERT`, `UPDATE` or `DELETE` keyword in a SQL statement. Multiple hints can be specified by separating with commas. For example, the following query uses three different hints: diff --git a/sql-plan-management.md b/sql-plan-management.md index 7f8a6d2258e62..e91f3871bb598 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -484,6 +484,52 @@ SHOW binding_cache status; 1 row in set (0.00 sec) ``` +## Utilize Statement Summary table to obtain queries that need to be bound + +[Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, corresponding query plans, etc. You can query Statement Summary to get qualified `plan_digest`, and [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). + +The following example searches for SELECT statements that have been executed more than 10 times in the past 2 weeks, have unstable execution plans, and have not been bound. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. + +```sql +WITH stmts AS ( -- Gets all information + SELECT * FROM INFORMATION_SCHEMA.CLUSTER_STATEMENTS_SUMMARY + UNION ALL + SELECT * FROM INFORMATION_SCHEMA.CLUSTER_STATEMENTS_SUMMARY_HISTORY +), +best_plans AS ( + SELECT plan_digest, `digest`, avg_latency, + CONCAT('create global binding from history using plan digest "', plan_digest, '"') as binding_stmt + FROM stmts t1 + WHERE avg_latency = (SELECT min(avg_latency) FROM stmts t2 -- The plan with the lowest query latency + WHERE t2.`digest` = t1.`digest`) +) + +SELECT any_value(digest_text) as query, + SUM(exec_count) as exec_count, + plan_hint, binding_stmt +FROM stmts, best_plans +WHERE stmts.`digest` = best_plans.`digest` + AND summary_begin_time > DATE_SUB(NOW(), interval 14 day) -- Executed in the past 2 weeks + AND stmt_type = 'Select' -- Only consider select statements + AND schema_name NOT IN ('INFORMATION_SCHEMA', 'mysql') -- Not an internal query + AND plan_in_binding = 0 -- No binding yet +GROUP BY stmts.`digest` + HAVING COUNT(DISTINCT(stmts.plan_digest)) > 1 -- This query is unstable. It has more than 1 plan. + AND SUM(exec_count) > 10 -- High-frequency, and has been executed more than 10 times. +ORDER BY SUM(exec_count) DESC LIMIT 100; -- Top 100 high-frequency queries. +``` + +By applying certain filtering conditions to obtain queries that meet the criteria, you can then directly execute the statements corresponding to the `binding_stmt` column to create bindings. + +``` ++---------------------------------------------+------------+-----------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------+ +| query | exec_count | plan_hint | binding_stmt | ++---------------------------------------------+------------+-----------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------+ +| select * from `t` where `a` = ? and `b` = ? | 401 | use_index(@`sel_1` `test`.`t` `a`), no_order_index(@`sel_1` `test`.`t` `a`) | create global binding from history using plan digest "0d6e97fb1191bbd08dddefa7bd007ec0c422b1416b152662768f43e64a9958a6" | +| select * from `t` where `b` = ? and `c` = ? | 104 | use_index(@`sel_1` `test`.`t` `b`), no_order_index(@`sel_1` `test`.`t` `b`) | create global binding from history using plan digest "80c2aa0aa7e6d3205755823aa8c6165092c8521fb74c06a9204b8d35fc037dd9" | ++---------------------------------------------+------------+-----------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------+ +``` + ## Cross-database binding Starting from v7.6.0, you can create cross-database bindings in TiDB by using the wildcard `*` to represent a database name in the binding creation syntax. Before creating cross-database bindings, you need to first enable the [`tidb_opt_enable_fuzzy_binding`](/system-variables.md#tidb_opt_enable_fuzzy_binding-new-in-v760) system variable. diff --git a/system-variables.md b/system-variables.md index 01e26e42449c3..722bdced6e0f8 100644 --- a/system-variables.md +++ b/system-variables.md @@ -3356,6 +3356,16 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified +### `tidb_load_binding_timeout` 从 v8.0.0 版本开始引入 + +- Scope: GLOBAL +- Persists to cluster: Yes +- Applies to hint [SET_VAR](/optimizer-hints.md#set_varvar_namevar_value): No +- Default value: `200` +- Range: `(0, 2147483647]` +- Unit: Milliseconds +- This variable is used to control the timeout of binding loading. If the time of binding loading exceeds this variable, it will stop. + ### `tidb_lock_unchanged_keys` New in v7.1.1 and v7.3.0 - Scope: SESSION | GLOBAL From c36454d7567c0e7cb41f17ab5018a1107a5e4f76 Mon Sep 17 00:00:00 2001 From: qw4990 Date: Thu, 14 Mar 2024 18:42:51 +0800 Subject: [PATCH 02/13] fixup --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index e91f3871bb598..c348e87c956f0 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -236,7 +236,7 @@ To make the execution plan of a SQL statement fixed to a historical execution pl When using this feature, note the following: - The feature generates hints according to historical execution plans and uses the generated hints for binding. Because historical execution plans are stored in [Statement Summary Tables](/statement-summary-tables.md), before using this feature, you need to enable the [`tidb_enable_stmt_summary`](/system-variables.md#tidb_enable_stmt_summary-new-in-v304) system variable first. -- This feature does not support TiFlash queries, Join queries with three or more tables, and queries that contain subqueries. +- For TiFlash queries, Join queries with three or more tables, and queries that contain subqueries, auto-generated hints might not be complete and able to fix the plan completely, for such cases a warning will be outputted. - If a historical execution plan is for a SQL statement with hints, the hints will be added to the binding. For example, after executing `SELECT /*+ max_execution_time(1000) */ * FROM t`, the binding created with its `plan_digest` will include `max_execution_time(1000)`. The SQL statement of this binding method is as follows: From c516779b79ab9cdfabe68cb0265889e4d54ab864 Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:18:32 +0800 Subject: [PATCH 03/13] Update system-variables.md Co-authored-by: xixirangrang --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index 722bdced6e0f8..b9e719a4bd032 100644 --- a/system-variables.md +++ b/system-variables.md @@ -3356,7 +3356,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified -### `tidb_load_binding_timeout` 从 v8.0.0 版本开始引入 +### `tidb_load_binding_timeout` New in v8.0.0 - Scope: GLOBAL - Persists to cluster: Yes From d161271948baa711e98590ffda7770da98a3ae43 Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:36:46 +0800 Subject: [PATCH 04/13] Update system-variables.md Co-authored-by: xixirangrang --- system-variables.md | 1 + 1 file changed, 1 insertion(+) diff --git a/system-variables.md b/system-variables.md index b9e719a4bd032..4203d63f66fe2 100644 --- a/system-variables.md +++ b/system-variables.md @@ -3361,6 +3361,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - Scope: GLOBAL - Persists to cluster: Yes - Applies to hint [SET_VAR](/optimizer-hints.md#set_varvar_namevar_value): No +- Type: Integer - Default value: `200` - Range: `(0, 2147483647]` - Unit: Milliseconds From b8d9adb44c0c0892115ecb59677e3bd793fd1132 Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:53:19 +0800 Subject: [PATCH 05/13] Update sql-plan-management.md Co-authored-by: xixirangrang --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index c348e87c956f0..d25535038f57c 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -519,7 +519,7 @@ GROUP BY stmts.`digest` ORDER BY SUM(exec_count) DESC LIMIT 100; -- Top 100 high-frequency queries. ``` -By applying certain filtering conditions to obtain queries that meet the criteria, you can then directly execute the statements corresponding to the `binding_stmt` column to create bindings. +By applying certain filtering conditions to obtain queries that meet the criteria, you can then directly execute the statements in the corresponding `binding_stmt` column to create bindings. ``` +---------------------------------------------+------------+-----------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------+ From 6b719c34e08daae49152561128bd0c11a5482b4b Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:53:46 +0800 Subject: [PATCH 06/13] Update sql-plan-management.md Co-authored-by: xixirangrang --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index d25535038f57c..e8e89cb149580 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -236,7 +236,7 @@ To make the execution plan of a SQL statement fixed to a historical execution pl When using this feature, note the following: - The feature generates hints according to historical execution plans and uses the generated hints for binding. Because historical execution plans are stored in [Statement Summary Tables](/statement-summary-tables.md), before using this feature, you need to enable the [`tidb_enable_stmt_summary`](/system-variables.md#tidb_enable_stmt_summary-new-in-v304) system variable first. -- For TiFlash queries, Join queries with three or more tables, and queries that contain subqueries, auto-generated hints might not be complete and able to fix the plan completely, for such cases a warning will be outputted. +- For TiFlash queries, Join queries with three or more tables, and queries that contain subqueries, the auto-generated hints are not complete enough, which might result in the plan not being fully bound. In such cases, a warning will occur when creating a binding. - If a historical execution plan is for a SQL statement with hints, the hints will be added to the binding. For example, after executing `SELECT /*+ max_execution_time(1000) */ * FROM t`, the binding created with its `plan_digest` will include `max_execution_time(1000)`. The SQL statement of this binding method is as follows: From c5b0134a1c322210da7a8551e238f66b18a9ea2f Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:53:51 +0800 Subject: [PATCH 07/13] Update sql-plan-management.md Co-authored-by: xixirangrang --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index e8e89cb149580..a6b651bc1a8a0 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -484,7 +484,7 @@ SHOW binding_cache status; 1 row in set (0.00 sec) ``` -## Utilize Statement Summary table to obtain queries that need to be bound +## Utilize the Statement Summary table to obtain queries that need to be bound [Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, corresponding query plans, etc. You can query Statement Summary to get qualified `plan_digest`, and [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). From 1a3edbddf18b53cb5b6a5d9748b08bdd7affc51c Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:53:58 +0800 Subject: [PATCH 08/13] Update sql-plan-management.md Co-authored-by: xixirangrang --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index a6b651bc1a8a0..0ba3043178495 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -486,7 +486,7 @@ SHOW binding_cache status; ## Utilize the Statement Summary table to obtain queries that need to be bound -[Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, corresponding query plans, etc. You can query Statement Summary to get qualified `plan_digest`, and [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). +[Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, and corresponding query plans. You can query Statement Summary to get qualified `plan_digest`, and then [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). The following example searches for SELECT statements that have been executed more than 10 times in the past 2 weeks, have unstable execution plans, and have not been bound. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. From 7decf5c585d6d49ebf7a966d471532e3c0365035 Mon Sep 17 00:00:00 2001 From: Yuanjia Zhang Date: Thu, 14 Mar 2024 21:54:04 +0800 Subject: [PATCH 09/13] Update sql-plan-management.md Co-authored-by: xixirangrang --- sql-plan-management.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index 0ba3043178495..f4c791a618b2c 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -488,7 +488,7 @@ SHOW binding_cache status; [Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, and corresponding query plans. You can query Statement Summary to get qualified `plan_digest`, and then [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). -The following example searches for SELECT statements that have been executed more than 10 times in the past 2 weeks, have unstable execution plans, and have not been bound. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. +The following example searches for SELECT statements that have been executed more than 10 times in the past two weeks, have unstable execution plans, and have not been bound. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. ```sql WITH stmts AS ( -- Gets all information From 909ff2ae07600c7564404affc19575585544f7a8 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Mon, 18 Mar 2024 09:42:11 +0800 Subject: [PATCH 10/13] Apply suggestions from code review Co-authored-by: Roger Song --- sql-plan-management.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index f4c791a618b2c..fcb224be24bd2 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -236,7 +236,7 @@ To make the execution plan of a SQL statement fixed to a historical execution pl When using this feature, note the following: - The feature generates hints according to historical execution plans and uses the generated hints for binding. Because historical execution plans are stored in [Statement Summary Tables](/statement-summary-tables.md), before using this feature, you need to enable the [`tidb_enable_stmt_summary`](/system-variables.md#tidb_enable_stmt_summary-new-in-v304) system variable first. -- For TiFlash queries, Join queries with three or more tables, and queries that contain subqueries, the auto-generated hints are not complete enough, which might result in the plan not being fully bound. In such cases, a warning will occur when creating a binding. +- For TiFlash queries, Join queries with three or more tables, and queries that contain subqueries, the auto-generated hints are not adequate, which might result in the plan not being fully bound. In such cases, a warning will occur when creating a binding. - If a historical execution plan is for a SQL statement with hints, the hints will be added to the binding. For example, after executing `SELECT /*+ max_execution_time(1000) */ * FROM t`, the binding created with its `plan_digest` will include `max_execution_time(1000)`. The SQL statement of this binding method is as follows: @@ -488,7 +488,7 @@ SHOW binding_cache status; [Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, and corresponding query plans. You can query Statement Summary to get qualified `plan_digest`, and then [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). -The following example searches for SELECT statements that have been executed more than 10 times in the past two weeks, have unstable execution plans, and have not been bound. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. +The following example searches for SELECT statements that have been executed more than 10 times in the past two weeks, and have multiple execution plans without SQL binding. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. ```sql WITH stmts AS ( -- Gets all information From dfe3dd855a56ef52ccb735bc15e72264caa56870 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Mon, 18 Mar 2024 10:57:53 +0800 Subject: [PATCH 11/13] Update sql-plan-management.md Co-authored-by: Aolin --- sql-plan-management.md | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/sql-plan-management.md b/sql-plan-management.md index fcb224be24bd2..e402c92b4d7c6 100644 --- a/sql-plan-management.md +++ b/sql-plan-management.md @@ -484,11 +484,11 @@ SHOW binding_cache status; 1 row in set (0.00 sec) ``` -## Utilize the Statement Summary table to obtain queries that need to be bound +## Utilize the statement summary table to obtain queries that need to be bound -[Statement Summary](/statement-summary-tables.md) stores recent SQL execution information, such as latency, execution times, and corresponding query plans. You can query Statement Summary to get qualified `plan_digest`, and then [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). +[Statement summary](/statement-summary-tables.md) records recent SQL execution information, such as latency, execution times, and corresponding query plans. You can query statement summary tables to get qualified `plan_digest`, and then [create bindings according to these historical execution plans](/sql-plan-management.md#create-a-binding-according-to-a-historical-execution-plan). -The following example searches for SELECT statements that have been executed more than 10 times in the past two weeks, and have multiple execution plans without SQL binding. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. +The following example queries `SELECT` statements that have been executed more than 10 times in the past two weeks, and have multiple execution plans without SQL binding. It sorts the queries by the execution times, and binds the top 100 queries to their fastest plans. ```sql WITH stmts AS ( -- Gets all information From b2958fed03574587657c997e6795757141eb0f7c Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Mon, 18 Mar 2024 11:12:47 +0800 Subject: [PATCH 12/13] Update system-variables.md --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index 4203d63f66fe2..cffd3ae061d1e 100644 --- a/system-variables.md +++ b/system-variables.md @@ -3365,7 +3365,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - Default value: `200` - Range: `(0, 2147483647]` - Unit: Milliseconds -- This variable is used to control the timeout of binding loading. If the time of binding loading exceeds this variable, it will stop. +- This variable is used to control the timeout of binding loading. If the execution time of loading bindings exceeds this value, the loading will be stopped. ### `tidb_lock_unchanged_keys` New in v7.1.1 and v7.3.0 From c771a47c8449bf7b410f5e29f9a9b4be0c594321 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Tue, 19 Mar 2024 12:54:42 +0800 Subject: [PATCH 13/13] Update system-variables.md --- system-variables.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/system-variables.md b/system-variables.md index cffd3ae061d1e..2bc0dd819e9d0 100644 --- a/system-variables.md +++ b/system-variables.md @@ -3365,7 +3365,7 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified - Default value: `200` - Range: `(0, 2147483647]` - Unit: Milliseconds -- This variable is used to control the timeout of binding loading. If the execution time of loading bindings exceeds this value, the loading will be stopped. +- This variable is used to control the timeout of loading bindings. If the execution time of loading bindings exceeds this value, the loading will stop. ### `tidb_lock_unchanged_keys` New in v7.1.1 and v7.3.0