From 94b1eba53ceb327043b499c4bf3c34ef05d186b7 Mon Sep 17 00:00:00 2001 From: Aolin Date: Thu, 6 Mar 2025 19:07:52 +0800 Subject: [PATCH 1/6] Add new Index advisor user doc --- TOC.md | 1 + index-advisor.md | 223 +++++++++++++++++++++++++++++++++++++++++ sql-tuning-overview.md | 1 + 3 files changed, 225 insertions(+) create mode 100644 index-advisor.md diff --git a/TOC.md b/TOC.md index 9ec73504a40c..7a06e9749118 100644 --- a/TOC.md +++ b/TOC.md @@ -368,6 +368,7 @@ - [执行计划管理](/sql-plan-management.md) - [优化规则及表达式下推的黑名单](/blocklist-control-plan.md) - [Optimizer Fix Controls](/optimizer-fix-controls.md) + - [索引推荐 (Index Advisor)](/index-advisor.md) - 教程 - [单区域多 AZ 部署](/multi-data-centers-in-one-city-deployment.md) - [双区域多 AZ 部署](/three-data-centers-in-two-cities-deployment.md) diff --git a/index-advisor.md b/index-advisor.md new file mode 100644 index 000000000000..04f0ef3a0cef --- /dev/null +++ b/index-advisor.md @@ -0,0 +1,223 @@ +--- +title: 索引推荐 (Index Advisor) +summary: 了解如何使用 TiDB 索引推荐 (Index Advisor) 功能优化查询性能。 +--- + +# 索引推荐 (Index Advisor) + +从 v8.5.0 开始,TiDB 引入索引推荐 (Index Advisor) 功能,通过推荐能提高查询性能的索引来帮助优化工作负载。你可以使用 `RECOMMEND INDEX` SQL 语句为单个查询或整个工作负载生成索引建议。为了避免物理创建索引这一资源密集型的评估过程,TiDB 支持[虚拟索引 (Hypothetical indexes)](#虚拟索引-hypothetical-indexes),这些是存在于逻辑层面而不会被实际物化的索引。 + +索引推荐功能通过分析查询语句,从 `WHERE`、`GROUP BY` 和 `ORDER BY` 等子句中识别可索引的列。然后,它会生成索引候选项并使用虚拟索引估算其性能收益。TiDB 采用遗传搜索算法,从单列索引开始逐步探索多列索引组合,利用假设分析评估潜在索引对优化器计划成本的影响。当索引能够降低总体查询成本时,索引推荐功能会推荐这些索引。 + +除了[推荐新索引](#使用-recommend-index-语句推荐索引),索引推荐功能还会建议[删除未使用的索引](#删除未使用的索引),以确保高效的索引管理。 + +## 使用 `RECOMMEND INDEX` 语句推荐索引 + +TiDB 提供 `RECOMMEND INDEX` SQL 语句用于索引推荐任务。使用 `RUN` 子命令,可以分析历史工作负载并将推荐结果保存到系统表中。使用 `FOR` 选项,可以为特定 SQL 语句生成索引建议,即使该语句未执行过。你还可以使用[其他选项](#recommend-index-选项)进行高级控制。语法如下: + +```sql +RECOMMEND INDEX RUN [ FOR ] [] +``` + +### 为单个查询推荐索引 + +以下示例展示如何为表 `t` 上的查询生成索引建议,该表包含 5,000 行数据。为简洁起见,以下示例省略了 `INSERT` 语句。 + +```sql +CREATE TABLE t (a INT, b INT, c INT); +RECOMMEND INDEX RUN for "SELECT a, b FROM t WHERE a = 1 AND b = 1"\G +*************************** 1. row *************************** + database: test + table: t + index_name: idx_a_b + index_columns: a,b + est_index_size: 0 + reason: Column [a b] appear in Equal or Range Predicate clause(s) in query: select `a` , `b` from `test` . `t` where `a` = ? and `b` = ? + top_impacted_query: [{"Query":"SELECT `a`,`b` FROM `test`.`t` WHERE `a` = 1 AND `b` = 1","Improvement":0.999994}] +create_index_statement: CREATE INDEX idx_a_b ON t(a,b); +``` + +索引推荐功能分别评估 `a` 和 `b` 上的单列索引,并最终将它们合并为一个组合索引以优化性能。 + +以下 `EXPLAIN` 结果比较了无索引和使用推荐的两列虚拟索引的查询执行计划。索引推荐功能在内部评估这两种方案,并选择成本最低的选项。索引推荐功能还会考虑 `a` 和 `b` 上的单列虚拟索引,但在这种情况下,这些索引的性能不如组合的两列索引(为简洁起见,省略了这些执行计划)。 + +```sql +EXPLAIN FORMAT='VERBOSE' SELECT a, b FROM t WHERE a=1 AND b=1; + ++-------------------------+---------+------------+-----------+---------------+----------------------------------+ +| id | estRows | estCost | task | access object | operator info | ++-------------------------+---------+------------+-----------+---------------+----------------------------------+ +| TableReader_7 | 0.01 | 196066.71 | root | | data:Selection_6 | +| └─Selection_6 | 0.01 | 2941000.00 | cop[tikv] | | eq(test.t.a, 1), eq(test.t.b, 1) | +| └─TableFullScan_5 | 5000.00 | 2442000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | ++-------------------------+---------+------------+-----------+---------------+----------------------------------+ + +EXPLAIN FORMAT='VERBOSE' SELECT /*+ HYPO_INDEX(t, idx_ab, a, b) */ a, b FROM t WHERE a=1 AND b=1; ++------------------------+---------+---------+-----------+-----------------------------+-------------------------------------------------+ +| id | estRows | estCost | task | access object | operator info | ++------------------------+---------+---------+-----------+-----------------------------+-------------------------------------------------+ +| IndexReader_6 | 0.05 | 1.10 | root | | index:IndexRangeScan_5 | +| └─IndexRangeScan_5 | 0.05 | 10.18 | cop[tikv] | table:t, index:idx_ab(a, b) | range:[1 1,1 1], keep order:false, stats:pseudo | ++------------------------+---------+---------+-----------+-----------------------------+-------------------------------------------------+ +``` + +### 为工作负载推荐索引 + +以下示例展示如何为整个工作负载生成索引推荐。假设表 `t1` 和 `t2` 各包含 5,000 行数据: + +```sql +CREATE TABLE t1 (a INT, b INT, c INT, d INT); +CREATE TABLE t2 (a INT, b INT, c INT, d INT); + +-- 在此工作负载中运行一些查询 +SELECT a, b FROM t1 WHERE a=1 AND b<=5; +SELECT d FROM t1 ORDER BY d LIMIT 10; +SELECT * FROM t1, t2 WHERE t1.a=1 AND t1.d=t2.d; + +RECOMMEND INDEX RUN; ++----------+-------+------------+---------------+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------------------+ +| database | table | index_name | index_columns | est_index_size | reason | top_impacted_query | create_index_statement | ++----------+-------+------------+---------------+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------------------+ +| test | t1 | idx_a_b | a,b | 19872 | Column [a b] appear in Equal or Range Predicate clause(s) in query: select `a` , `b` from `test` . `t1` where `a` = ? and `b` <= ? | [{"Query":"SELECT `a`,`b` FROM `test`.`t1` WHERE `a` = 1 AND `b` \u003c= 5","Improvement":0.998214},{"Query":"SELECT * FROM (`test`.`t1`) JOIN `test`.`t2` WHERE `t1`.`a` = 1 AND `t1`.`d` = `t2`.`d`","Improvement":0.336837}] | CREATE INDEX idx_a_b ON t1(a,b); | +| test | t1 | idx_d | d | 9936 | Column [d] appear in Equal or Range Predicate clause(s) in query: select `d` from `test` . `t1` order by `d` limit ? | [{"Query":"SELECT `d` FROM `test`.`t1` ORDER BY `d` LIMIT 10","Improvement":0.999433}] | CREATE INDEX idx_d ON t1(d); | +| test | t2 | idx_d | d | 9936 | Column [d] appear in Equal or Range Predicate clause(s) in query: select * from ( `test` . `t1` ) join `test` . `t2` where `t1` . `a` = ? and `t1` . `d` = `t2` . `d` | [{"Query":"SELECT * FROM (`test`.`t1`) JOIN `test`.`t2` WHERE `t1`.`a` = 1 AND `t1`.`d` = `t2`.`d`","Improvement":0.638567}] | CREATE INDEX idx_d ON t2(d); | ++----------+-------+------------+---------------+------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+----------------------------------+ +``` + +在这个示例中,索引推荐功能识别出了适用于整个工作负载的最佳索引,而不仅仅是针对单个查询。工作负载查询来源于 TiDB 系统表 `INFORMATION_SCHEMA.STATEMENTS_SUMMARY`。 + +该系统表可能包含数万到数十万条查询,这可能会影响索引推荐功能的性能。为解决这个问题,索引推荐功能优先考虑执行频率最高的查询,因为这些查询对整体工作负载性能的影响更大。默认情况下,索引推荐功能选择前 1,000 条查询,你可以使用 [`max_num_query`](#recommend-index-选项) 参数调整此值。 + +`RECOMMEND INDEX` 语句的结果存储在 `mysql.index_advisor_results` 表中。你可以查询此表以查看推荐的索引。以下示例为执行前两个 `RECOMMEND INDEX` 语句后此系统表的内容: + +```sql +SELECT * FROM mysql.index_advisor_results; ++----+---------------------+---------------------+-------------+------------+------------+---------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------+-------+ +| id | created_at | updated_at | schema_name | table_name | index_name | index_columns | index_details | top_impacted_queries | workload_impact | extra | ++----+---------------------+---------------------+-------------+------------+------------+---------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------+-------+ +| 1 | 2024-12-10 11:44:45 | 2024-12-10 11:44:45 | test | t1 | idx_a_b | a,b | {"IndexSize": 0, "Reason": "Column [a b] appear in Equal or Range Predicate clause(s) in query: select `a` , `b` from `test` . `t1` where `a` = ? and `b` <= ?"} | [{"Improvement": 0.998214, "Query": "SELECT `a`,`b` FROM `test`.`t1` WHERE `a` = 1 AND `b` <= 5"}, {"Improvement": 0.337273, "Query": "SELECT * FROM (`test`.`t1`) JOIN `test`.`t2` WHERE `t1`.`a` = 1 AND `t1`.`d` = `t2`.`d`"}] | {"WorkloadImprovement": 0.395235} | NULL | +| 2 | 2024-12-10 11:44:45 | 2024-12-10 11:44:45 | test | t1 | idx_d | d | {"IndexSize": 0, "Reason": "Column [d] appear in Equal or Range Predicate clause(s) in query: select `d` from `test` . `t1` order by `d` limit ?"} | [{"Improvement": 0.999715, "Query": "SELECT `d` FROM `test`.`t1` ORDER BY `d` LIMIT 10"}] | {"WorkloadImprovement": 0.225116} | NULL | +| 3 | 2024-12-10 11:44:45 | 2024-12-10 11:44:45 | test | t2 | idx_d | d | {"IndexSize": 0, "Reason": "Column [d] appear in Equal or Range Predicate clause(s) in query: select * from ( `test` . `t1` ) join `test` . `t2` where `t1` . `a` = ? and `t1` . `d` = `t2` . `d`"} | [{"Improvement": 0.639393, "Query": "SELECT * FROM (`test`.`t1`) JOIN `test`.`t2` WHERE `t1`.`a` = 1 AND `t1`.`d` = `t2`.`d`"}] | {"WorkloadImprovement": 0.365871} | NULL | ++----+---------------------+---------------------+-------------+------------+------------+---------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------+-------+ +``` + +### `RECOMMEND INDEX` 选项 + +你可以配置和查看 `RECOMMEND INDEX` 语句的选项,以根据你的工作负载需求调整其行为,如下所示: + +```sql +RECOMMEND INDEX SET