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 #16770

Merged
merged 27 commits into from
Mar 19, 2024
Merged
Changes from 13 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
48 changes: 48 additions & 0 deletions sql-plan-management.md
Original file line number Diff line number Diff line change
Expand Up @@ -476,6 +476,54 @@ SHOW binding_cache status;
1 row in set (0.00 sec)
```

## 利用 `Statement Summary` 表获取需要绑定的查询
qw4990 marked this conversation as resolved.
Show resolved Hide resolved

[`Statement Summary`](/statement-summary-tables.md) 的表中存放了近期的 SQL 相关的执行信息,如延迟、执行次数、对应计划等,通过编写特定的查询访问这些表,可以快速找到需要绑定的查询。
Oreoxmt marked this conversation as resolved.
Show resolved Hide resolved

你可以通过查询 `Statement Summary` 表得到符合条件查询的 `plan_digest`,再使用[根据历史执行计划创建绑定](/sql-plan-management.md#根据历史执行计划创建绑定)快速创建绑定。
Oreoxmt marked this conversation as resolved.
Show resolved Hide resolved

下面是一个实例,此实例会查找过去 2 周执行次数超过 10 次,执行计划不稳定且未被绑定的 Select 语句,按照执行次数排序,将执行次数前 100 的查询绑定到对应的查询延迟最低的计划上:
qw4990 marked this conversation as resolved.
Show resolved Hide resolved

```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 loweset query latency
qw4990 marked this conversation as resolved.
Show resolved Hide resolved
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-grequency queries.
qw4990 marked this conversation as resolved.
Show resolved Hide resolved
```

通过一些过滤条件得到满足条件的查询,然后直接运行 `binding_stmt` 列对应的语句即可创建相应的绑定。

```
+---------------------------------------------+------------+-----------------------------------------------------------------------------+-------------------------------------------------------------------------------------------------------------------------+
| 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-DB Binding)

在创建绑定的 SQL 语句中,TiDB 支持使用通配符 `*` 表示数据库,实现跨数据库绑定。该功能自 v7.6.0 开始引入。要使用跨数据库绑定,首先需要开启 [`tidb_opt_enable_fuzzy_binding`](/system-variables.md#tidb_opt_enable_fuzzy_binding-从-v760-版本开始引入) 系统变量。
Expand Down
Loading