-
Notifications
You must be signed in to change notification settings - Fork 1.2k
perf-tuning: Add document for topn-limit-push-down (#3307) #3753
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
Merged
yikeke
merged 4 commits into
pingcap:release-3.1
from
ti-srebot:release-3.1-75c37dc259bd
Jun 28, 2020
Merged
Changes from all commits
Commits
Show all changes
4 commits
Select commit
Hold shift + click to select a range
File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,124 @@ | ||
| --- | ||
LittleFall marked this conversation as resolved.
Show resolved
Hide resolved
|
||
| title: TopN 和 Limit 下推 | ||
| category: performance | ||
| --- | ||
|
|
||
| # TopN 和 Limit 下推 | ||
|
|
||
| SQL 中的 LIMIT 子句在 TiDB 查询计划树中对应 Limit 算子节点,ORDER BY 子句在查询计划树中对应 Sort 算子节点,此外,我们会将相邻的 Limit 和 Sort 算子组合成 TopN 算子节点,表示按某个排序规则提取记录的前 N 项。从另一方面来说,Limit 节点等价于一个排序规则为空的 TopN 节点。 | ||
|
|
||
| 和谓词下推类似,TopN(及 Limit,下同)下推将查询计划树中的 TopN 计算尽可能下推到距离数据源最近的地方,以尽早完成数据的过滤,进而显著地减少数据传输或计算的开销。 | ||
|
|
||
| 如果要关闭这个规则,可参照[优化规则及表达式下推的黑名单](/blacklist-control-plan.md)中的关闭方法。 | ||
|
|
||
| ## 示例 | ||
|
|
||
| 以下通过一些例子对 TopN 下推进行说明。 | ||
|
|
||
| ### 示例 1:下推到存储层 Coprocessor | ||
|
|
||
| {{< copyable "sql" >}} | ||
|
|
||
| ```sql | ||
| create table t(id int primary key, a int not null); | ||
| explain select * from t order by a limit 10; | ||
| ``` | ||
|
|
||
| ``` | ||
| +----------------------------+----------+-----------+---------------+--------------------------------+ | ||
| | id | estRows | task | access object | operator info | | ||
| +----------------------------+----------+-----------+---------------+--------------------------------+ | ||
| | TopN_7 | 10.00 | root | | test.t.a, offset:0, count:10 | | ||
| | └─TableReader_15 | 10.00 | root | | data:TopN_14 | | ||
| | └─TopN_14 | 10.00 | cop[tikv] | | test.t.a, offset:0, count:10 | | ||
| | └─TableFullScan_13 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | | ||
| +----------------------------+----------+-----------+---------------+--------------------------------+ | ||
| 4 rows in set (0.00 sec) | ||
| ``` | ||
|
|
||
| 在该查询中,将 TopN 算子节点下推到 TiKV 上对数据进行过滤,每个 Coprocessor 只向 TiDB 传输 10 条记录。在 TiDB 将数据整合后,再进行最终的过滤。 | ||
|
|
||
| ### 示例 2:TopN 下推过 Join 的情况(排序规则仅依赖于外表中的列) | ||
|
|
||
| {{< copyable "sql" >}} | ||
|
|
||
| ```sql | ||
| create table t(id int primary key, a int not null); | ||
| create table s(id int primary key, a int not null); | ||
| explain select * from t left join s on t.a = s.a order by t.a limit 10; | ||
| ``` | ||
|
|
||
| ``` | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| | id | estRows | task | access object | operator info | | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| | TopN_12 | 10.00 | root | | test.t.a, offset:0, count:10 | | ||
| | └─HashJoin_17 | 12.50 | root | | left outer join, equal:[eq(test.t.a, test.s.a)] | | ||
| | ├─TopN_18(Build) | 10.00 | root | | test.t.a, offset:0, count:10 | | ||
| | │ └─TableReader_26 | 10.00 | root | | data:TopN_25 | | ||
| | │ └─TopN_25 | 10.00 | cop[tikv] | | test.t.a, offset:0, count:10 | | ||
| | │ └─TableFullScan_24 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | | ||
| | └─TableReader_30(Probe) | 10000.00 | root | | data:TableFullScan_29 | | ||
| | └─TableFullScan_29 | 10000.00 | cop[tikv] | table:s | keep order:false, stats:pseudo | | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| 8 rows in set (0.01 sec) | ||
| ``` | ||
|
|
||
| 在该查询中,TopN 算子的排序规则仅依赖于外表 t 中的列,可以将 TopN 下推到 Join 之前进行一次计算,以减少 Join 时的计算开销。除此之外,TiDB 同样将 TopN 下推到了存储层中。 | ||
|
|
||
| ### 示例 3:TopN 不能下推过 Join 的情况 | ||
|
|
||
| {{< copyable "sql" >}} | ||
|
|
||
| ```sql | ||
| create table t(id int primary key, a int not null); | ||
| create table s(id int primary key, a int not null); | ||
| explain select * from t join s on t.a = s.a order by t.id limit 10; | ||
| ``` | ||
|
|
||
| ``` | ||
| +-------------------------------+----------+-----------+---------------+--------------------------------------------+ | ||
| | id | estRows | task | access object | operator info | | ||
| +-------------------------------+----------+-----------+---------------+--------------------------------------------+ | ||
| | TopN_12 | 10.00 | root | | test.t.id, offset:0, count:10 | | ||
| | └─HashJoin_16 | 12500.00 | root | | inner join, equal:[eq(test.t.a, test.s.a)] | | ||
| | ├─TableReader_21(Build) | 10000.00 | root | | data:TableFullScan_20 | | ||
| | │ └─TableFullScan_20 | 10000.00 | cop[tikv] | table:s | keep order:false, stats:pseudo | | ||
| | └─TableReader_19(Probe) | 10000.00 | root | | data:TableFullScan_18 | | ||
| | └─TableFullScan_18 | 10000.00 | cop[tikv] | table:t | keep order:false, stats:pseudo | | ||
| +-------------------------------+----------+-----------+---------------+--------------------------------------------+ | ||
| 6 rows in set (0.00 sec) | ||
| ``` | ||
|
|
||
| TopN 无法下推过 Inner Join。以上面的查询为例,如果先 Join 得到 100 条记录,再做 TopN 可以剩余 10 条记录。而如果在 TopN 之前就过滤到剩余 10 条记录,做完 Join 之后可能就剩下 5 条了,导致了结果的差异。 | ||
|
|
||
| 同理,TopN 无法下推到 Outer Join 的内表上。在 TopN 的排序规则涉及多张表上的列时,也无法下推,如 `t.a+s.a`。只有当 TopN 的排序规则仅依赖于外表上的列时,才可以下推。 | ||
|
|
||
| ### 示例 4:TopN 转换成 Limit 的情况 | ||
|
|
||
| {{< copyable "sql" >}} | ||
|
|
||
| ```sql | ||
| create table t(id int primary key, a int not null); | ||
| create table s(id int primary key, a int not null); | ||
| explain select * from t left join s on t.a = s.a order by t.id limit 10; | ||
| ``` | ||
|
|
||
| ``` | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| | id | estRows | task | access object | operator info | | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| | TopN_12 | 10.00 | root | | test.t.id, offset:0, count:10 | | ||
| | └─HashJoin_17 | 12.50 | root | | left outer join, equal:[eq(test.t.a, test.s.a)] | | ||
| | ├─Limit_21(Build) | 10.00 | root | | offset:0, count:10 | | ||
| | │ └─TableReader_31 | 10.00 | root | | data:Limit_30 | | ||
| | │ └─Limit_30 | 10.00 | cop[tikv] | | offset:0, count:10 | | ||
| | │ └─TableFullScan_29 | 10.00 | cop[tikv] | table:t | keep order:true, stats:pseudo | | ||
| | └─TableReader_35(Probe) | 10000.00 | root | | data:TableFullScan_34 | | ||
| | └─TableFullScan_34 | 10000.00 | cop[tikv] | table:s | keep order:false, stats:pseudo | | ||
| +----------------------------------+----------+-----------+---------------+-------------------------------------------------+ | ||
| 8 rows in set (0.00 sec) | ||
|
|
||
| ``` | ||
|
|
||
| 在上面的查询中,TopN 首先推到了外表 t 上。然后因为它要对 `t.id` 进行排序,而 `t.id` 是表 t 的主键,可以直接按顺序读出 (`keep order:true`),从而省略了 TopN 中的排序,将其简化为 Limit。 | ||
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
Uh oh!
There was an error while loading. Please reload this page.