From ba7fbe30475b36dfd6cbcf10c26f62ec7584899f Mon Sep 17 00:00:00 2001 From: Lloyd-Pottiger Date: Sun, 27 Apr 2025 14:29:45 +0800 Subject: [PATCH 1/5] tiflash: support inverted index Signed-off-by: Lloyd-Pottiger --- tiflash/tiflash-inverted-index.md | 175 ++++++++++++++++++++++++ tiflash/tiflash-late-materialization.md | 4 - vector-search/vector-search-index.md | 2 +- 3 files changed, 176 insertions(+), 5 deletions(-) create mode 100644 tiflash/tiflash-inverted-index.md diff --git a/tiflash/tiflash-inverted-index.md b/tiflash/tiflash-inverted-index.md new file mode 100644 index 000000000000..14ef7311df02 --- /dev/null +++ b/tiflash/tiflash-inverted-index.md @@ -0,0 +1,175 @@ +--- +title: 数值列倒排索引 +summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP 场景的查询。 +--- + +# 数值列倒排索引 + +倒排索引是信息检索领域常用的索引技术。它将文本划分为单个词,并构建词->文档 ID 索引,以便快速搜索确定哪些文档包含特定的词。 + +对于数值列(整数、时间和日期类型),我们可以简化存储从数字到其在列中位置的映射(值 → rowid)。因此,使用倒排索引,可以快速查找包含特定值的行,从而加快 WHERE 子句的处理速度。 + +## 使用限制 + +- 集群需要提前部署 TiFlash 节点。 +- 数值列倒排索引不能作为主键或者唯一索引。 +- 数值列倒排索引只能基于单一的数值列创建,不能与其他列组合形成复合索引。 +- 不支持直接删除具有数值列倒排索引的列。可以通过先删除列上的数值列倒排索引,再删除列的方式完成删除。 +- 不支持对带有数值列倒排索引的列进行 [Reorg 类型变更](/sql-statements/sql-statement-modify-column.md)。 +- 不支持将数值列倒排索引[设置为不可见](/sql-statements/sql-statement-alter-index.md)。 +- 不支持在开启了[静态加密](/encryption-at-rest.md)的 TiFlash 节点上构建数值列倒排索引。 + +## 创建数值列倒排索引 + +在 TiDB 中,你可以通过以下任一种方式为数值列创建倒排索引。 + +- 在建表时,使用以下语法来指定为哪一个列创建数值列倒排索引: + + ```sql + CREATE TABLE foo ( + id INT PRIMARY KEY, + count INT, + create_date DATE, + COLUMNAR INDEX idx_count (count) USING INVERTED, + COLUMNAR INDEX idx_create_date (create_date) USING INVERTED + ); + ``` + +- 对于现有的表,可以通过以下语法为数值列创建倒排索引: + + ```sql + CREATE COLUMNAR INDEX idx_count ON foo (count) USING INVERTED; + ALTER TABLE foo ADD COLUMNAR INDEX idx_count (count) USING INVERTED; + ``` + +> **注意:** +> +> 数值列倒排索引功能的实现需要基于表的 TiFlash 副本。 +> +> - 在建表时如果定义了数值列倒排索引,TiDB 将自动为该表创建一个 TiFlash 副本。 +> - 如果建表时未定义数值列倒排索引,并且该表当前没有 TiFlash 副本,那么为该表添加数值列倒排索引时,你需要先手动为该表创建 TiFlash 副本,例如:`ALTER TABLE 'table_name' SET TIFLASH REPLICA 1;`。 + +## 使用数值列倒排索引 + +数值列倒排索引支持包含 =, !=, >, >=, <, <=, in 的过滤条件,TiDB 优化器会自动选择使用倒排索引来加速查询,如下所示: + +```sql +SELECT * +FROM foo +WHERE count > 10; +``` + +带有多个过滤条件的 WHERE 子句也可以使用数值列倒排索引: + +```sql +SELECT * +FROM foo +WHERE count > 10 AND create_date = '2023-01-01'; +``` + +## 查看索引构建进度 + +当插入大批量数据后,部分数据可能没有立即持久化到 TiFlash 中。对于已经持久化的向量数据,数值列倒排索引是通过同步的方式构建的;对于尚未未持久化的数据,数值列倒排索引会在数据持久化后才开始构建,但这并不会影响数据的准确性和一致性。你仍然可以随时进行查询,并获得完整的结果,但需要注意的是,查询性能只有在数值列倒排索引完全构建好之后才会达到最佳水平。 + +要查看索引构建进度,可以按如下方式查询 `INFORMATION_SCHEMA.TIFLASH_INDEXES` 表: + +```sql +SELECT * FROM INFORMATION_SCHEMA.TIFLASH_INDEXES; ++---------------+------------+----------+-------------+-----------------+-----------+----------+------------+---------------------+-------------------------+--------------------+------------------------+---------------+------------------+ +| TIDB_DATABASE | TIDB_TABLE | TABLE_ID | COLUMN_NAME | INDEX_NAME | COLUMN_ID | INDEX_ID | INDEX_KIND | ROWS_STABLE_INDEXED | ROWS_STABLE_NOT_INDEXED | ROWS_DELTA_INDEXED | ROWS_DELTA_NOT_INDEXED | ERROR_MESSAGE | TIFLASH_INSTANCE | ++---------------+------------+----------+-------------+-----------------+-----------+----------+------------+---------------------+-------------------------+--------------------+------------------------+---------------+------------------+ +| test | foo | 112 | count | idx_count | 2 | 1 | Inverted | 1 | 0 | 0 | 0 | | 127.0.0.1:3930 | +| test | foo | 112 | create_date | idx_create_date | 3 | 2 | Inverted | 1 | 0 | 0 | 0 | | 127.0.0.1:3930 | ++---------------+------------+----------+-------------+-----------------+-----------+----------+------------+---------------------+-------------------------+--------------------+------------------------+---------------+------------------+ +``` + +- 可以通过 `ROWS_STABLE_INDEXED` 和 `ROWS_STABLE_NOT_INDEXED` 列查看索引构建进度。当 `ROWS_STABLE_NOT_INDEXED` 变为 0 时,表示索引构建完成。 + +- 可以通过 `ROWS_DELTA_NOT_INDEXED` 列查看 Delta 层中的行数。TiFlash 存储层的数据主要存放在 Delta 层和 Stable 层。Delta 层存储最近插入或更新的行,并根据写入工作量定期将这些行合并到 Stable 层。这个合并过程称为“压缩”。 + + Delta 层可能仅有部分数据是包含索引的,为了达到最佳性能,你可以强制将 Delta 层合并到 Stable 层,以确保所有的数据都能够被索引: + + ```sql + ALTER TABLE COMPACT; + ``` + + 更多信息,请参阅 [`ALTER TABLE ... COMPACT`](/sql-statements/sql-statement-alter-table-compact.md)。 + +此外,你也可以通过 `ADMIN SHOW DDL JOBS;` 查看 DDL 任务的执行进度,观察其 `row count`。不过这种方式并不准确,`row count` 的值是从 `TIFLASH_INDEXES` 里的 `rows_stable_indexed` 获取的。你也可以使用此方式查看索引构建进度。 + +## 查看是否使用了数值列倒排索引 + +你可以使用 [`EXPLAIN`](/sql-statements/sql-statement-explain.md) 或 [`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md) 语句查看一个查询是否使用了数值列倒排索引。如果 `TableFullScan` 执行计划的 `operator info` 列中出现了 `invertedIndex:`,表示 TiDB 在扫描该表时使用了数值列倒排索引。 + +**示例:使用了向量索引的查询** + +```sql +[tidb]> EXPLAIN SELECT * FROM foo WHERE count < 10; ++-----+-----------------------------------------------------------------------------------+ +| ... | operator info | ++-----+-----------------------------------------------------------------------------------+ +| ... | MppVersion: 3, data:ExchangeSender_12 | +| ... | ExchangeType: PassThrough | +| ... | lt(test.foo.count, 10) | +| ... | pushed down filter:empty, keep order:false, stats:pseudo, invertedIndex:idx_count | ++-----+-----------------------------------------------------------------------------------+ +4 rows in set (0.00 sec) +[tidb]> EXPLAIN SELECT * FROM foo WHERE create_date < DATE('2025-05-01'); ++-----+-----------------------------------------------------------------------------------------+ +| ... | operator info | ++-----+-----------------------------------------------------------------------------------------+ +| ... | MppVersion: 3, data:ExchangeSender_12 | +| ... | ExchangeType: PassThrough | +| ... | lt(test.foo.create_date, 2025-05-01) | +| ... | pushed down filter:empty, keep order:false, stats:pseudo, invertedIndex:idx_create_date | ++-----+-----------------------------------------------------------------------------------------+ +4 rows in set (0.00 sec) +``` + +**示例:由于过滤条件过滤效果不佳,优化器选择不使用数值列倒排索引的查询** + +```sql +[tidb]> EXPLAIN SELECT * FROM foo WHERE create_date != DATE('2025-05-01'); ++-----+----------------------------------------------------------+ +| ... | operator info | ++-----+----------------------------------------------------------+ +| ... | MppVersion: 3, data:ExchangeSender_12 | +| ... | ExchangeType: PassThrough | +| ... | ne(test.foo.create_date, 2025-05-01) | +| ... | pushed down filter:empty, keep order:false, stats:pseudo | ++-----+----------------------------------------------------------+ +4 rows in set (0.00 sec) +``` + +## 分析向量搜索性能 + +你可以执行 [`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md) 语句,然后查看输出中的 `execution info` 列了解向量索引使用情况的详细信息: + +```sql +[tidb]> EXPLAIN ANALYZE SELECT * FROM foo WHERE create_date > DATE('2025-05-01'); ++-----+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----+ +| | execution info | | ++-----+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----+ +| ... | time:9.47ms, open:1.2ms, close:8.47µs, loops:1, RU:1.00, cop_task: {num: 1, max: 0s, proc_keys: 0, copr_cache_hit_ratio: 0.00} | ... | +| ... | tiflash_task:{time:6.36ms, loops:0, threads:72} | ... | +| ... | tiflash_task:{time:5.36ms, loops:0, threads:72} | ... | +| ... | tiflash_task:{...}, inverted_idx:{load:{total:13ms,from_s3:0,from_disk:0,from_cache:864},search:{total:986ms,skipped_packs:29765,indexed_rows:600011622,selected_rows:845092}} ... | ... | ++-----+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----+ +``` + +> **注意:** +> +> 执行信息为 TiDB 内部信息。字段和格式如有更改,恕不另行通知。请勿依赖。 + +以下为一些重要字段的解释: + +- `inverted_idx.load.total`:加载索引的总时长。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行加载多个向量索引。 +- `inverted_idx.load.from_s3`:从 S3 加载的索引数量。 +- `inverted_idx.load.from_disk`:从磁盘加载的索引数量。这些索引之前已经从 S3 下载到磁盘上。 +- `inverted_idx.load.from_cache`:从缓存中加载的索引数量。这些索引之前已经从 S3 下载并存储在缓存中。 +- `inverted_idx.search.total`:在索引中搜索的总时长。如果该时间存在较大的延迟,通常意味着该索引为冷索引(以前从未被访问过,或很久以前被访问过),因此在索引中搜索时会产生较多的 I/O 操作。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行搜索多个向量索引。 +- `inverted_idx.search.skipped_packs`:在搜索过程中跳过的 Pack 的数量。Pack 是 TiFlash 中存储数据的基本单位。TiFlash 会将数据分成多个 Pack 进行存储和索引。该字段的值越大,表示在搜索过程中跳过的 Pack 越多,减少的 I/O 操作越多。 +- `inverted_idx.search.indexed_rows`:被索引的总行数。 +- `inverted_idx.search.selected_rows`:在搜索过程中被选中的总行数。 + +关于执行信息输出的更多信息,请参阅 [`EXPLAIN`](/sql-statements/sql-statement-explain.md)、[`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md),以及[使用 `EXPLAIN` 解读执行计划](/explain-walkthrough.md)。 diff --git a/tiflash/tiflash-late-materialization.md b/tiflash/tiflash-late-materialization.md index 659e25670c06..bddf025548e4 100644 --- a/tiflash/tiflash-late-materialization.md +++ b/tiflash/tiflash-late-materialization.md @@ -5,10 +5,6 @@ summary: 介绍通过使用 TiFlash 延迟物化的方式来加速 OLAP 场景 # 延迟物化 -> **注意:** -> -> 在 TiFlash [Fast Scan 模式](/tiflash/use-fastscan.md)下,延迟物化功能暂不可用。 - TiFlash 延迟物化是加速 Online Analytical Processing (OLAP) 场景查询的一种优化方式。你可以通过修改变量 [`tidb_opt_enable_late_materialization`](/system-variables.md#tidb_opt_enable_late_materialization-从-v700-版本开始引入) 来控制是否启用 TiFlash 延迟物化功能。 - 当关闭该功能时,如果 `SELECT` 语句中包含过滤条件(`WHERE` 子句),TiFlash 会先读取该查询所需列的全部数据,然后再根据查询条件对数据进行过滤、聚合等计算任务。 diff --git a/vector-search/vector-search-index.md b/vector-search/vector-search-index.md index 7ed8953b8b66..bb099c9573a5 100644 --- a/vector-search/vector-search-index.md +++ b/vector-search/vector-search-index.md @@ -134,7 +134,7 @@ SELECT * FROM INFORMATION_SCHEMA.TIFLASH_INDEXES; - 可以通过 `ROWS_DELTA_NOT_INDEXED` 列查看 Delta 层中的行数。TiFlash 存储层的数据主要存放在 Delta 层和 Stable 层。Delta 层存储最近插入或更新的行,并根据写入工作量定期将这些行合并到 Stable 层。这个合并过程称为“压缩”。 - Delta 层本身是不包含索引的。为了达到最佳性能,你可以强制将 Delta 层合并到 Stable 层,以确保所有的数据都能够被索引: + Delta 层可能仅有部分数据是包含索引的,为了达到最佳性能,你可以强制将 Delta 层合并到 Stable 层,以确保所有的数据都能够被索引: ```sql ALTER TABLE COMPACT; From df37d2db088911eeabaa2e8f88c53d2b9dfc14c7 Mon Sep 17 00:00:00 2001 From: Lloyd-Pottiger Date: Tue, 29 Apr 2025 13:45:20 +0800 Subject: [PATCH 2/5] address comments Signed-off-by: Lloyd-Pottiger --- tiflash/tiflash-inverted-index.md | 38 +++++++++++++++++++------------ 1 file changed, 23 insertions(+), 15 deletions(-) diff --git a/tiflash/tiflash-inverted-index.md b/tiflash/tiflash-inverted-index.md index 14ef7311df02..bcd6abbd5fb9 100644 --- a/tiflash/tiflash-inverted-index.md +++ b/tiflash/tiflash-inverted-index.md @@ -9,15 +9,13 @@ summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP 对于数值列(整数、时间和日期类型),我们可以简化存储从数字到其在列中位置的映射(值 → rowid)。因此,使用倒排索引,可以快速查找包含特定值的行,从而加快 WHERE 子句的处理速度。 -## 使用限制 +## 适用场景 -- 集群需要提前部署 TiFlash 节点。 -- 数值列倒排索引不能作为主键或者唯一索引。 -- 数值列倒排索引只能基于单一的数值列创建,不能与其他列组合形成复合索引。 -- 不支持直接删除具有数值列倒排索引的列。可以通过先删除列上的数值列倒排索引,再删除列的方式完成删除。 -- 不支持对带有数值列倒排索引的列进行 [Reorg 类型变更](/sql-statements/sql-statement-modify-column.md)。 -- 不支持将数值列倒排索引[设置为不可见](/sql-statements/sql-statement-alter-index.md)。 -- 不支持在开启了[静态加密](/encryption-at-rest.md)的 TiFlash 节点上构建数值列倒排索引。 +数值列倒排索引在 TiFlash 中构建,支持数值、日期时间类型的 =, !=, >, >=, <, <=, in 快速过滤,在以下场景中数值列倒排索引有明显优势: + +- 过滤条件过滤率高,但过滤后行数依然较多。TiFlash 批量读取性能可能优于 TiKV 索引回表。 +- 查询包含 IndexMerge 或 IndexJoin 算子,但 TiKV 索引命中行数多导致性能差。将 IndexJoin 转化为 HashJoin,下推到 TiFlash 节点进行计算,利用 MPP 并行降低查询延迟。 +- 查询 WHERE 子句同时包含简单等值、范围过滤条件和复杂函数过滤条件。数值列倒排索引帮忙提前过滤掉不满足简单等值、范围过滤条件的行,从而减少复杂函数过滤条件的计算量。 ## 创建数值列倒排索引 @@ -51,7 +49,7 @@ summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP ## 使用数值列倒排索引 -数值列倒排索引支持包含 =, !=, >, >=, <, <=, in 的过滤条件,TiDB 优化器会自动选择使用倒排索引来加速查询,如下所示: +TiDB 优化器会自动选择使用倒排索引来加速查询,如下所示: ```sql SELECT * @@ -69,7 +67,7 @@ WHERE count > 10 AND create_date = '2023-01-01'; ## 查看索引构建进度 -当插入大批量数据后,部分数据可能没有立即持久化到 TiFlash 中。对于已经持久化的向量数据,数值列倒排索引是通过同步的方式构建的;对于尚未未持久化的数据,数值列倒排索引会在数据持久化后才开始构建,但这并不会影响数据的准确性和一致性。你仍然可以随时进行查询,并获得完整的结果,但需要注意的是,查询性能只有在数值列倒排索引完全构建好之后才会达到最佳水平。 +当插入大批量数据后,部分数据可能没有立即持久化到 TiFlash 中。对于已经持久化的数据,数值列倒排索引是通过同步的方式构建的;对于尚未未持久化的数据,数值列倒排索引会在数据持久化后才开始构建,但这并不会影响数据的准确性和一致性。你仍然可以随时进行查询,并获得完整的结果,但需要注意的是,查询性能只有在数值列倒排索引完全构建好之后才会达到最佳水平。 要查看索引构建进度,可以按如下方式查询 `INFORMATION_SCHEMA.TIFLASH_INDEXES` 表: @@ -101,7 +99,7 @@ SELECT * FROM INFORMATION_SCHEMA.TIFLASH_INDEXES; 你可以使用 [`EXPLAIN`](/sql-statements/sql-statement-explain.md) 或 [`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md) 语句查看一个查询是否使用了数值列倒排索引。如果 `TableFullScan` 执行计划的 `operator info` 列中出现了 `invertedIndex:`,表示 TiDB 在扫描该表时使用了数值列倒排索引。 -**示例:使用了向量索引的查询** +**示例:使用了数值列倒排索引的查询** ```sql [tidb]> EXPLAIN SELECT * FROM foo WHERE count < 10; @@ -141,9 +139,9 @@ SELECT * FROM INFORMATION_SCHEMA.TIFLASH_INDEXES; 4 rows in set (0.00 sec) ``` -## 分析向量搜索性能 +## 分析数值列倒排索引性能 -你可以执行 [`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md) 语句,然后查看输出中的 `execution info` 列了解向量索引使用情况的详细信息: +你可以执行 [`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md) 语句,然后查看输出中的 `execution info` 列了解数值列倒排索引使用情况的详细信息: ```sql [tidb]> EXPLAIN ANALYZE SELECT * FROM foo WHERE create_date > DATE('2025-05-01'); @@ -163,13 +161,23 @@ SELECT * FROM INFORMATION_SCHEMA.TIFLASH_INDEXES; 以下为一些重要字段的解释: -- `inverted_idx.load.total`:加载索引的总时长。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行加载多个向量索引。 +- `inverted_idx.load.total`:加载索引的总时长。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行加载多个数值列倒排索引。 - `inverted_idx.load.from_s3`:从 S3 加载的索引数量。 - `inverted_idx.load.from_disk`:从磁盘加载的索引数量。这些索引之前已经从 S3 下载到磁盘上。 - `inverted_idx.load.from_cache`:从缓存中加载的索引数量。这些索引之前已经从 S3 下载并存储在缓存中。 -- `inverted_idx.search.total`:在索引中搜索的总时长。如果该时间存在较大的延迟,通常意味着该索引为冷索引(以前从未被访问过,或很久以前被访问过),因此在索引中搜索时会产生较多的 I/O 操作。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行搜索多个向量索引。 +- `inverted_idx.search.total`:在索引中搜索的总时长。如果该时间存在较大的延迟,通常意味着该索引为冷索引(以前从未被访问过,或很久以前被访问过),因此在索引中搜索时会产生较多的 I/O 操作。该字段的值可能会超过查询实际耗时,因为 TiDB 可能会并行搜索多个数值列倒排索引。 - `inverted_idx.search.skipped_packs`:在搜索过程中跳过的 Pack 的数量。Pack 是 TiFlash 中存储数据的基本单位。TiFlash 会将数据分成多个 Pack 进行存储和索引。该字段的值越大,表示在搜索过程中跳过的 Pack 越多,减少的 I/O 操作越多。 - `inverted_idx.search.indexed_rows`:被索引的总行数。 - `inverted_idx.search.selected_rows`:在搜索过程中被选中的总行数。 关于执行信息输出的更多信息,请参阅 [`EXPLAIN`](/sql-statements/sql-statement-explain.md)、[`EXPLAIN ANALYZE`](/sql-statements/sql-statement-explain-analyze.md),以及[使用 `EXPLAIN` 解读执行计划](/explain-walkthrough.md)。 + +## 使用限制 + +- 集群需要提前部署 TiFlash 节点。 +- 数值列倒排索引不能作为主键或者唯一索引。 +- 数值列倒排索引只能基于单一的数值列创建,不能与其他列组合形成复合索引。 +- 不支持直接删除具有数值列倒排索引的列。可以通过先删除列上的数值列倒排索引,再删除列的方式完成删除。 +- 不支持对带有数值列倒排索引的列进行 [Reorg 类型变更](/sql-statements/sql-statement-modify-column.md)。 +- 不支持将数值列倒排索引[设置为不可见](/sql-statements/sql-statement-alter-index.md)。 +- 不支持在开启了[静态加密](/encryption-at-rest.md)的 TiFlash 节点上构建数值列倒排索引。 From 33dedfdf2716846a6dbc38d96535e91753c94210 Mon Sep 17 00:00:00 2001 From: Lloyd-Pottiger <60744015+Lloyd-Pottiger@users.noreply.github.com> Date: Sat, 3 May 2025 14:53:35 +0800 Subject: [PATCH 3/5] Update tiflash/tiflash-inverted-index.md Co-authored-by: Wenxuan --- tiflash/tiflash-inverted-index.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tiflash/tiflash-inverted-index.md b/tiflash/tiflash-inverted-index.md index bcd6abbd5fb9..e869757152ae 100644 --- a/tiflash/tiflash-inverted-index.md +++ b/tiflash/tiflash-inverted-index.md @@ -14,7 +14,7 @@ summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP 数值列倒排索引在 TiFlash 中构建,支持数值、日期时间类型的 =, !=, >, >=, <, <=, in 快速过滤,在以下场景中数值列倒排索引有明显优势: - 过滤条件过滤率高,但过滤后行数依然较多。TiFlash 批量读取性能可能优于 TiKV 索引回表。 -- 查询包含 IndexMerge 或 IndexJoin 算子,但 TiKV 索引命中行数多导致性能差。将 IndexJoin 转化为 HashJoin,下推到 TiFlash 节点进行计算,利用 MPP 并行降低查询延迟。 +- 查询条件涉及多列,每列单独过滤后都留存有大量数据,但组合所有列进行过滤后行数较少。此时可以使用倒排索引,在 TiFlash 本地进行索引组合过滤,降低查询延迟。 - 查询 WHERE 子句同时包含简单等值、范围过滤条件和复杂函数过滤条件。数值列倒排索引帮忙提前过滤掉不满足简单等值、范围过滤条件的行,从而减少复杂函数过滤条件的计算量。 ## 创建数值列倒排索引 From 6d22fcc1e19afea1d7321d02d60f33d66683e79d Mon Sep 17 00:00:00 2001 From: Lloyd-Pottiger Date: Wed, 7 May 2025 20:55:37 +0800 Subject: [PATCH 4/5] address comments Signed-off-by: Lloyd-Pottiger --- tiflash/tiflash-inverted-index.md | 87 +++++++++++++++++++++++++++++++ 1 file changed, 87 insertions(+) diff --git a/tiflash/tiflash-inverted-index.md b/tiflash/tiflash-inverted-index.md index e869757152ae..dfe6404c7672 100644 --- a/tiflash/tiflash-inverted-index.md +++ b/tiflash/tiflash-inverted-index.md @@ -17,6 +17,93 @@ summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP - 查询条件涉及多列,每列单独过滤后都留存有大量数据,但组合所有列进行过滤后行数较少。此时可以使用倒排索引,在 TiFlash 本地进行索引组合过滤,降低查询延迟。 - 查询 WHERE 子句同时包含简单等值、范围过滤条件和复杂函数过滤条件。数值列倒排索引帮忙提前过滤掉不满足简单等值、范围过滤条件的行,从而减少复杂函数过滤条件的计算量。 +以下测试基于 TpC-H 50G 数据集,表 lineitem 中 L_PARTKEY 列和 L_SHIPDATE 列分别添加了数值倒排索引和普通索引。对比同一个查询 index merge,延迟物化和数值倒排索引的性能。从测试结果来看,利用数值列倒排索引查询延迟降低接近 50%。 + +```sql +mysql> alter table lineitem add index (L_PARTKEY); +Query OK, 0 rows affected (3 min 48.71 sec) + +mysql> alter table lineitem add index (L_SHIPDATE); +Query OK, 0 rows affected (4 min 6.41 sec) + +mysql> alter table lineitem add columnar index (L_PARTKEY) using inverted; +Query OK, 0 rows affected (13.27 sec) + +mysql> alter table lineitem add columnar index (L_SHIPDATE) using inverted; +Query OK, 0 rows affected (1.26 sec) + +mysql> show create table lineitem; ++----------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ +| Table | Create Table | ++----------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ +| lineitem | CREATE TABLE `lineitem` ( + `L_ORDERKEY` bigint NOT NULL, + `L_PARTKEY` bigint NOT NULL, + `L_SUPPKEY` bigint NOT NULL, + `L_LINENUMBER` bigint NOT NULL, + `L_QUANTITY` decimal(15,2) NOT NULL, + `L_EXTENDEDPRICE` decimal(15,2) NOT NULL, + `L_DISCOUNT` decimal(15,2) NOT NULL, + `L_TAX` decimal(15,2) NOT NULL, + `L_RETURNFLAG` char(1) NOT NULL, + `L_LINESTATUS` char(1) NOT NULL, + `L_SHIPDATE` date NOT NULL, + `L_COMMITDATE` date NOT NULL, + `L_RECEIPTDATE` date NOT NULL, + `L_SHIPINSTRUCT` char(25) NOT NULL, + `L_SHIPMODE` char(10) NOT NULL, + `L_COMMENT` varchar(44) NOT NULL, + PRIMARY KEY (`L_ORDERKEY`,`L_LINENUMBER`) /*T![clustered_index] CLUSTERED */, + COLUMNAR INDEX `L_PARTKEY`(`L_PARTKEY`) USING INVERTED, + COLUMNAR INDEX `L_SHIPDATE`(`L_SHIPDATE`) USING INVERTED, + KEY `L_PARTKEY_2` (`L_PARTKEY`), + KEY `L_SHIPDATE_2` (`L_SHIPDATE`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin | ++----------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+ +1 row in set (0.00 sec) + +# index merge +mysql> explain analyze select /*+ USE_INDEX_MERGE(lineitem, L_PARTKEY_2, L_SHIPDATE_2) */ count(*) from lineitem where L_PARTKEY < 5000 and L_SHIPDATE = DATE('1996-03-13'); ++----------------------------------+-------------+---------+-----------+------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------+----------+---------+ +| id | estRows | actRows | task | access object | execution info | operator info | memory | disk | ++----------------------------------+-------------+---------+-----------+------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------+----------+---------+ +| HashAgg_7 | 1.00 | 1 | root | | time:194.4ms, open:46.5µs, close:9µs, loops:2, RU:247.96, partial_worker:{wall_time:194.304554ms, concurrency:5, task_num:1, tot_wait:194.228682ms, tot_exec:24.741µs, tot_time:971.379544ms, max:194.283547ms, p95:194.283547ms}, final_worker:{wall_time:194.323503ms, concurrency:5, task_num:5, tot_wait:39.253µs, tot_exec:135ns, tot_time:971.508466ms, max:194.310791ms, p95:194.310791ms} | funcs:count(1)->Column#17 | 11.8 KB | 0 Bytes | +| └─IndexMerge_14 | 53.41 | 63 | root | | time:194.2ms, open:7.35µs, close:6.38µs, loops:2, index_task:{fetch_handle:226.2887ms, merge:191.799255ms}, table_task:{num:1, concurrency:5, fetch_row:2.37452ms, wait_time:191.799845ms} | type: intersection | 148.1 MB | N/A | +| ├─IndexRangeScan_11(Build) | 99701931.19 | 149567 | cop[tikv] | table:lineitem, index:L_PARTKEY_2(L_PARTKEY) | time:87ms, open:0s, close:0s, loops:149, cop_task: {num: 5, max: 38.2ms, min: 419.8µs, avg: 23.7ms, p95: 38.2ms, max_proc_keys: 50144, p95_proc_keys: 50144, copr_cache_hit_ratio: 0.00, build_task_duration: 25.9µs, max_distsql_concurrency: 2}, rpc_info:{Cop:{num_rpc:5, total_time:118.6ms}}, tikv_task:{proc max:35ms, min:0s, avg: 21.4ms, p80:35ms, p95:35ms, iters:164, tasks:5}, scan_detail: {total_process_keys: 149567, total_process_keys_size: 8525319, total_keys: 149572, get_snapshot_time: 92.4µs, rocksdb: {key_skipped_count: 149567, block: {cache_hit_count: 282}}}, time_detail: {total_wait_time: 208.7µs, total_kv_read_wall_time: 107ms, tikv_grpc_process_time: 136.7µs, tikv_grpc_wait_time: 112.5µs, tikv_wall_time: 115.2ms} | range:[-inf,5000), keep order:false, stats:partial[l_partkey_2:missing, l_shipdate_2:missing] | N/A | N/A | +| ├─IndexRangeScan_12(Build) | 300005.81 | 124551 | cop[tikv] | table:lineitem, index:L_SHIPDATE_2(L_SHIPDATE) | time:64.2ms, open:0s, close:0s, loops:124, cop_task: {num: 4, max: 35.2ms, min: 9.69ms, avg: 22ms, p95: 35.2ms, max_proc_keys: 50144, p95_proc_keys: 50144, copr_cache_hit_ratio: 0.00, build_task_duration: 20.9µs, max_distsql_concurrency: 1}, rpc_info:{Cop:{num_rpc:4, total_time:88ms}}, tikv_task:{proc max:33ms, min:9ms, avg: 20ms, p80:33ms, p95:33ms, iters:138, tasks:4}, scan_detail: {total_process_keys: 124551, total_process_keys_size: 7099407, total_keys: 124555, get_snapshot_time: 70.6µs, rocksdb: {key_skipped_count: 124551, block: {cache_hit_count: 228}}}, time_detail: {total_wait_time: 160.8µs, total_kv_read_wall_time: 80ms, tikv_grpc_process_time: 112.2µs, tikv_grpc_wait_time: 89.7µs, tikv_wall_time: 85.4ms} | range:[1996-03-13,1996-03-13], keep order:false, stats:partial[l_partkey_2:missing, l_shipdate_2:missing] | N/A | N/A | +| └─TableRowIDScan_13(Probe) | 53.41 | 63 | cop[tikv] | table:lineitem | time:2.07ms, open:0s, close:5.39µs, loops:2, cop_task: {num: 54, max: 928.2µs, min: 0s, avg: 136.9µs, p95: 917.7µs, max_proc_keys: 3, p95_proc_keys: 2, tot_proc: 2.87ms, tot_wait: 1.9ms, copr_cache_hit_ratio: 0.00, build_task_duration: 165.8µs, max_distsql_concurrency: 1, max_extra_concurrency: 5, store_batch_num: 43}, rpc_info:{Cop:{num_rpc:11, total_time:7.21ms}}, tikv_task:{proc max:1ms, min:0s, avg: 55.6µs, p80:0s, p95:1ms, iters:54, tasks:54}, scan_detail: {total_process_keys: 63, total_process_keys_size: 12147, total_keys: 126, get_snapshot_time: 950.2µs, rocksdb: {key_skipped_count: 63, block: {cache_hit_count: 252}}}, time_detail: {total_process_time: 2.87ms, total_wait_time: 1.9ms, total_kv_read_wall_time: 3ms, tikv_grpc_process_time: 1.13ms, tikv_grpc_wait_time: 325.6µs, tikv_wall_time: 3.55ms} | keep order:false, stats:partial[l_partkey_2:missing, l_shipdate_2:missing] | N/A | N/A | ++----------------------------------+-------------+---------+-----------+------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------+----------+---------+ +5 rows in set (0.19 sec) + +# late materialization +mysql> explain analyze select count(*) from lineitem where L_PARTKEY < 5000 and L_SHIPDATE = DATE('1996-03-13'); ++--------------------------------+-----------+---------+--------------+----------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------+-----------+---------+ +| id | estRows | actRows | task | access object | execution info | operator info | memory | disk | ++--------------------------------+-----------+---------+--------------+----------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------+-----------+---------+ +| HashAgg_27 | 1.00 | 1 | root | | time:248.4ms, open:951.8µs, close:13.7µs, loops:2, RU:36331.12, partial_worker:{wall_time:247.433348ms, concurrency:5, task_num:1, tot_wait:247.374457ms, tot_exec:18.789µs, tot_time:1.237043864s, max:247.411834ms, p95:247.411834ms}, final_worker:{wall_time:247.444568ms, concurrency:5, task_num:5, tot_wait:48.988µs, tot_exec:134ns, tot_time:1.237154718s, max:247.434028ms, p95:247.434028ms} | funcs:count(Column#19)->Column#17 | 9.37 KB | 0 Bytes | +| └─TableReader_29 | 1.00 | 1 | root | | time:248.3ms, open:889.7µs, close:10.8µs, loops:2, cop_task: {num: 2, max: 0s, min: 0s, avg: 0s, p95: 0s, copr_cache_hit_ratio: 0.00} | MppVersion: 3, data:ExchangeSender_28 | 938 Bytes | N/A | +| └─ExchangeSender_28 | 1.00 | 1 | mpp[tiflash] | | tiflash_task:{time:245.5ms, loops:1, threads:1}, tiflash_network: {inner_zone_send_bytes: 24} | ExchangeType: PassThrough | N/A | N/A | +| └─HashAgg_10 | 1.00 | 1 | mpp[tiflash] | | tiflash_task:{time:245.5ms, loops:1, threads:1} | funcs:count(1)->Column#19 | N/A | N/A | +| └─Selection_26 | 53.41 | 63 | mpp[tiflash] | | tiflash_task:{time:244.5ms, loops:62, threads:72} | lt(test.lineitem.l_partkey, 5000) | N/A | N/A | +| └─TableFullScan_25 | 117394.85 | 122381 | mpp[tiflash] | table:lineitem | tiflash_task:{time:244.5ms, loops:4930, threads:72}, tiflash_wait: {pipeline_queue_wait: 5ms}, tiflash_scan:{mvcc_input_rows:0, mvcc_input_bytes:0, mvcc_output_rows:0, local_regions:217, remote_regions:0, tot_learner_read:4ms, region_balance:{instance_num: 1, max/min: 217/217=1.000000}, delta_rows:0, delta_bytes:0, segments:433, stale_read_regions:0, tot_build_snapshot:1ms, tot_build_bitmap:225ms, tot_build_inputstream:3050ms, min_local_stream:232ms, max_local_stream:236ms, dtfile:{data_scanned_rows:284284368, data_skipped_rows:298547871, mvcc_scanned_rows:0, mvcc_skipped_rows:0, lm_filter_scanned_rows:294833959, lm_filter_skipped_rows:5171852, tot_rs_index_check:1026ms, tot_read:10313ms}} | pushed down filter:eq(test.lineitem.l_shipdate, 1996-03-13), keep order:false | N/A | N/A | ++--------------------------------+-----------+---------+--------------+----------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------+-----------+---------+ +6 rows in set (0.25 sec) + +# inverted index +mysql> explain analyze select count(*) from lineitem where L_PARTKEY < 5000 and L_SHIPDATE = DATE('1996-03-13'); ++--------------------------------+---------+---------+--------------+--------------------------------------------------------------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------+-----------+---------+ +| id | estRows | actRows | task | access object | execution info | operator info | memory | disk | ++--------------------------------+---------+---------+--------------+--------------------------------------------------------------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------+-----------+---------+ +| HashAgg_27 | 1.00 | 1 | root | | time:98.7ms, open:1.16ms, close:12.7µs, loops:2, RU:128.00, partial_worker:{wall_time:97.519027ms, concurrency:5, task_num:1, tot_wait:97.455533ms, tot_exec:20µs, tot_time:487.473197ms, max:97.50304ms, p95:97.50304ms}, final_worker:{wall_time:97.542551ms, concurrency:5, task_num:5, tot_wait:4.81µs, tot_exec:141ns, tot_time:487.579108ms, max:97.527966ms, p95:97.527966ms} | funcs:count(Column#19)->Column#17 | 6.23 KB | 0 Bytes | +| └─TableReader_29 | 1.00 | 1 | root | | time:98.6ms, open:1.12ms, close:9.73µs, loops:2, cop_task: {num: 2, max: 0s, min: 0s, avg: 0s, p95: 0s, copr_cache_hit_ratio: 0.00} | MppVersion: 3, data:ExchangeSender_28 | 930 Bytes | N/A | +| └─ExchangeSender_28 | 1.00 | 1 | mpp[tiflash] | | tiflash_task:{time:95.5ms, loops:1, threads:1}, tiflash_network: {inner_zone_send_bytes: 24} | ExchangeType: PassThrough | N/A | N/A | +| └─HashAgg_10 | 1.00 | 1 | mpp[tiflash] | | tiflash_task:{time:95.5ms, loops:1, threads:1} | funcs:count(1)->Column#19 | N/A | N/A | +| └─Selection_26 | 53.41 | 63 | mpp[tiflash] | | tiflash_task:{time:95.5ms, loops:63, threads:72} | eq(test.lineitem.l_shipdate, 1996-03-13), lt(test.lineitem.l_partkey, 5000) | N/A | N/A | +| └─TableFullScan_25 | 53.41 | 63 | mpp[tiflash] | table:lineitem, index:L_PARTKEY(L_PARTKEY), index:L_SHIPDATE(L_SHIPDATE) | tiflash_task:{time:95.5ms, loops:63, threads:72}, tiflash_wait: {pipeline_queue_wait: 2ms}, inverted_idx:{load:{total:4ms,from_s3:0,from_disk:0,from_cache:864},search:{total:545ms,skipped_packs:36037,indexed_rows:600011622,selected_rows:274118}}, tiflash_scan:{mvcc_input_rows:0, mvcc_input_bytes:0, mvcc_output_rows:0, local_regions:217, remote_regions:0, tot_learner_read:4ms, region_balance:{instance_num: 1, max/min: 217/217=1.000000}, delta_rows:0, delta_bytes:0, segments:433, stale_read_regions:0, tot_build_snapshot:1ms, tot_build_bitmap:32ms, tot_build_inputstream:4836ms, min_local_stream:85ms, max_local_stream:87ms, dtfile:{data_scanned_rows:516096, data_skipped_rows:299489715, mvcc_scanned_rows:0, mvcc_skipped_rows:0, lm_filter_scanned_rows:0, lm_filter_skipped_rows:0, tot_rs_index_check:585ms, tot_read:84ms}} | pushed down filter:empty, keep order:false, invertedindex:l_partkey, l_shipdate | N/A | N/A | ++--------------------------------+---------+---------+--------------+--------------------------------------------------------------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+---------------------------------------------------------------------------------+-----------+---------+ +6 rows in set (0.10 sec) +``` + ## 创建数值列倒排索引 在 TiDB 中,你可以通过以下任一种方式为数值列创建倒排索引。 From 59e3cb7e2728f0dd40e1b2a4a01abc4943628d02 Mon Sep 17 00:00:00 2001 From: Lloyd-Pottiger <60744015+Lloyd-Pottiger@users.noreply.github.com> Date: Thu, 8 May 2025 09:56:46 +0800 Subject: [PATCH 5/5] Apply suggestions from code review Co-authored-by: JaySon --- tiflash/tiflash-inverted-index.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/tiflash/tiflash-inverted-index.md b/tiflash/tiflash-inverted-index.md index dfe6404c7672..82292dbfd501 100644 --- a/tiflash/tiflash-inverted-index.md +++ b/tiflash/tiflash-inverted-index.md @@ -17,7 +17,7 @@ summary: 了解如何在 TiDB 中构建并使用数值列倒排索引加速 OLAP - 查询条件涉及多列,每列单独过滤后都留存有大量数据,但组合所有列进行过滤后行数较少。此时可以使用倒排索引,在 TiFlash 本地进行索引组合过滤,降低查询延迟。 - 查询 WHERE 子句同时包含简单等值、范围过滤条件和复杂函数过滤条件。数值列倒排索引帮忙提前过滤掉不满足简单等值、范围过滤条件的行,从而减少复杂函数过滤条件的计算量。 -以下测试基于 TpC-H 50G 数据集,表 lineitem 中 L_PARTKEY 列和 L_SHIPDATE 列分别添加了数值倒排索引和普通索引。对比同一个查询 index merge,延迟物化和数值倒排索引的性能。从测试结果来看,利用数值列倒排索引查询延迟降低接近 50%。 +以下测试基于 TPC-H 50G 数据集,表 lineitem 中 L_PARTKEY 列和 L_SHIPDATE 列分别添加了数值倒排索引和普通索引。对同一个查询分别使用 index merge、延迟物化或数值倒排索引的性能。从测试结果来看,利用数值列倒排索引查询延迟降低接近 50%。 ```sql mysql> alter table lineitem add index (L_PARTKEY); @@ -75,7 +75,7 @@ mysql> explain analyze select /*+ USE_INDEX_MERGE(lineitem, L_PARTKEY_2, L_SHIPD +----------------------------------+-------------+---------+-----------+------------------------------------------------+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-----------------------------------------------------------------------------------------------------------+----------+---------+ 5 rows in set (0.19 sec) -# late materialization +# late materialization without inverted index mysql> explain analyze select count(*) from lineitem where L_PARTKEY < 5000 and L_SHIPDATE = DATE('1996-03-13'); +--------------------------------+-----------+---------+--------------+----------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------------------------+-----------+---------+ | id | estRows | actRows | task | access object | execution info | operator info | memory | disk |