Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

planner: update SPM doc #16772

Merged
merged 13 commits into from
Mar 19, 2024
2 changes: 1 addition & 1 deletion optimizer-hints.md
Original file line number Diff line number Diff line change
Expand Up @@ -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:

Expand Down
48 changes: 47 additions & 1 deletion sql-plan-management.md
Original file line number Diff line number Diff line change
Expand Up @@ -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, 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:
Expand Down Expand Up @@ -484,6 +484,52 @@ SHOW binding_cache status;
1 row in set (0.00 sec)
```

## Utilize the statement summary table to obtain queries that need to be bound

[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 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
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 in the corresponding `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.
Expand Down
11 changes: 11 additions & 0 deletions system-variables.md
Original file line number Diff line number Diff line change
Expand Up @@ -3356,6 +3356,17 @@ For a system upgraded to v5.0 from an earlier version, if you have not modified

</CustomContent>

### `tidb_load_binding_timeout` <span class="version-mark">New in v8.0.0</span>

- Scope: GLOBAL
- Persists to cluster: Yes
- Applies to hint [SET_VAR](/optimizer-hints.md#set_varvar_namevar_value): No
- Type: Integer
- Default value: `200`
qw4990 marked this conversation as resolved.
Show resolved Hide resolved
- Range: `(0, 2147483647]`
- Unit: Milliseconds
- 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` <span class="version-mark">New in v7.1.1 and v7.3.0</span>

- Scope: SESSION | GLOBAL
Expand Down
Loading