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
Show file tree
Hide file tree
Changes from 24 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
2 changes: 1 addition & 1 deletion optimizer-hints.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,7 +11,7 @@ TiDB 支持 Optimizer Hints 语法,它基于 MySQL 5.7 中介绍的类似 comm

## 语法

Optimizer Hints 不区分大小写,通过 `/*+ ... */` 注释的形式跟在 `SELECT`、`UPDATE` 或 `DELETE` 关键字的后面。`INSERT` 关键字后不支持 Optimizer Hints
Optimizer Hints 不区分大小写,通过 `/*+ ... */` 注释的形式跟在 `SELECT`、`INSERT`、`UPDATE` 或 `DELETE` 关键字的后面。

多个不同的 Hint 之间需用逗号隔开,例如:

Expand Down
48 changes: 47 additions & 1 deletion sql-plan-management.md
Original file line number Diff line number Diff line change
Expand Up @@ -227,7 +227,7 @@ CREATE BINDING FOR SELECT * FROM t WHERE a > 1 USING SELECT * FROM t use index(i
以下为根据历史执行计划创建绑定的注意事项:

- 该功能是根据历史的执行计划生成 hint 而实现的绑定,历史的执行计划来源是 [Statement Summary Tables](/statement-summary-tables.md),因此在使用此功能之前需开启系统变量 [`tidb_enable_stmt_summary`](/system-variables.md#tidb_enable_stmt_summary-从-v304-版本开始引入)。
- 对于包含子查询的查询、访问 TiFlash 的查询、3 张表或更多表进行 Join 的查询,目前还不支持通过历史执行计划进行绑定
- 对于包含子查询的查询、访问 TiFlash 的查询、3 张表或更多表进行 Join 的查询,自动生成的 hint 不够完备,可能导致无法完全固定住计划,对于这类情况在创建时会产生 warning
hfxsd marked this conversation as resolved.
Show resolved Hide resolved
- 原执行计划对应 SQL 语句中的 hint 也会被应用在创建的绑定中,如执行 `SELECT /*+ max_execution_time(1000) */ * FROM t` 后,使用其 `plan_digest` 创建的绑定中会带上 `max_execution_time(1000)`。

使用方式:
Expand Down Expand Up @@ -476,6 +476,52 @@ SHOW binding_cache status;
1 row in set (0.00 sec)
```

## 利用 Statement Summary 表获取需要绑定的查询

[Statement Summary](/statement-summary-tables.md) 的表中存放了近期的 SQL 相关的执行信息,如延迟、执行次数、对应计划等。你可以通过查询 Statement Summary 表得到符合条件查询的 `plan_digest`,然后[根据历史执行计划创建绑定](/sql-plan-management.md#根据历史执行计划创建绑定)。

以下示例查找过去 2 周执行次数超过 10 次、执行计划不稳定且未被绑定的 SELECT 语句,按照执行次数排序,将执行次数前 100 的查询绑定到对应的查询延迟最低的计划上。
hfxsd 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 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.
```

通过一些过滤条件得到满足条件的查询,然后直接运行 `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
10 changes: 10 additions & 0 deletions system-variables.md
Original file line number Diff line number Diff line change
Expand Up @@ -2910,6 +2910,16 @@ v5.0 后,用户仍可以单独修改以上系统变量(会有废弃警告)
- 类型:字符串
- 这个变量用来设置基于负载的 replica read 的触发阈值。当 leader 节点的预估排队时间超过阈值时,TiDB 会优先从 follower 节点读取数据。格式为时间,例如 `"100ms"` 或 `"1s"`。详情见 [TiDB 热点问题处理](/troubleshoot-hot-spot-issues.md#打散读热点)。

### `tidb_load_binding_timeout` <span class="version-mark">从 v8.0.0 版本开始引入</span>

- 作用域:GLOBAL
- 是否持久化到集群:是
- 是否受 Hint [SET_VAR](/optimizer-hints.md#set_varvar_namevar_value) 控制:否
- 默认值:`200`
qw4990 marked this conversation as resolved.
Show resolved Hide resolved
- 范围:`(0, 2147483647]`
- 单位:毫秒
- 这个变量用来控制 load binding 的超时时间。当 load binding 的执行时间超过该值时,会停止加载。
hfxsd marked this conversation as resolved.
Show resolved Hide resolved

### `tidb_lock_unchanged_keys` <span class="version-mark">从 v7.1.1 和 v7.3.0 版本开始引入</span>

- 作用域:SESSION | GLOBAL
Expand Down
Loading