-
Notifications
You must be signed in to change notification settings - Fork 3.8k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
opt: eliminate unnecessary index join inside group by
This commit adds a new exploration rule, EliminateIndexJoinInsideGroupBy. EliminateIndexJoinInsideGroupBy removes an IndexJoin operator if it can be proven that the removal does not affect the output of the parent grouping operator. This is the case if: 1. Only columns from the index join's input are being used by the grouping operator. 2. The OrderingChoice of the grouping operator can be expressed with only columns from the index join's input. Or in other words, at least one column in every ordering group is one of the output columns from the index join's input. This rule is useful when using partial indexes. When generating partial index scans, expressions can be removed from filters because they exactly match expressions in partial index predicates and there is no need to apply the filter after the scan. Columns referenced in the removed expressions may no longer need to be fetched. Consider the example: CREATE TABLE t (i INT, s STRING, INDEX (i) WHERE s IN ('foo','bar')) SELECT DISTINCT i FROM t WHERE s IN ('foo','bar') The normalized expression for the SELECT query is: distinct-on ├── columns: i:1 ├── grouping columns: i:1 └── select ├── columns: i:1 s:2!null ├── scan t │ └── columns: i:1 s:2 └── filters └── s:2 IN ('foo','bar') GeneratePartialIndexScans will generate this expression: distinct-on ├── columns: i:1 ├── grouping columns: i:1 └── index-join t ├── columns: i:1 s:2!null └── scan t@secondary,partial └── columns: i:1 rowid:4!null The IndexJoin is created because the Select expression in the previous expression required s in order to apply the (s IN ('foo','bar')) filter. However, because rows in the partial index are already filtered by (s IN ('foo','bar')), column s does not need to be fetched. The IndexJoin can be eliminated, resulting in the expression: distinct-on ├── columns: i:1 ├── grouping columns: i:1 └── scan t@secondary,partial └── columns: i:1 rowid:4!null This rule is needed to ensure that SplitGroupByScanIntoUnionScans can fire in order to create an efficient plan to validate new implicitly partitioned partial unique indexes. Fixes #65473 Release note (performance improvement): Validation of a new partial UNIQUE index in a REGIONAL BY ROW table no longer requires an inefficient and memory-intensive hash aggregation query. The optimizer can now plan the validation query so that it uses all streaming operations, which are much more efficient.
- Loading branch information
Showing
4 changed files
with
346 additions
and
3 deletions.
There are no files selected for viewing
This file contains 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 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 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 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