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

release-23.1.0: opt: hoist uncorrelated equality subqueries #101738

Closed

Conversation

mgartner
Copy link
Collaborator

@mgartner mgartner commented Apr 18, 2023

Backport 1/1 commits from #100881.

/cc @cockroachdb/release


opt: hoist uncorrelated equality subqueries

Subqueries that are in equality expressions with a variable are now
hoisted. When these expressions exist in a filter, hoisting the subquery
can allow the main query to plan a lookup join, rather than an
inefficient full-table scan.

For example, consider the table and query:

CREATE TABLE t (
  a INT,
  INDEX (a)
);

SELECT * FROM t WHERE a = (SELECT max(a) FROM t);

Prior to this commit, the query plan for this query required a full
table scan:

select
 ├── columns: a:1
 ├── scan t@t_a_idx
 │    ├── columns: a:1
 │    └── constraint: /1/2: (/NULL - ]
 └── filters
      └── eq
           ├── a:1
           └── subquery
                └── scalar-group-by
                     ├── columns: max:9
                     ├── scan t@t_a_idx,rev
                     │    ├── columns: a:5
                     │    ├── constraint: /5/6: (/NULL - ]
                     │    └── limit: 1(rev)
                     └── aggregations
                          └── const-agg [as=max:9, outer=(5)]
                               └── a:5

By hoisting the subquery, the full table scan is replaced with a lookup
join:

project
 ├── columns: a:1
 └── inner-join (lookup t@t_a_idx)
      ├── columns: a:1 max:9
      ├── key columns: [9] = [1]
      ├── scalar-group-by
      │    ├── columns: max:9
      │    ├── scan t@t_a_idx,rev
      │    │    ├── columns: a:5
      │    │    ├── constraint: /5/6: (/NULL - ]
      │    │    └── limit: 1(rev)
      │    └── aggregations
      │         └── const-agg [as=max:9, outer=(5)]
      │              └── a:5
      └── filters (true)

This hoisting is disabled by default, but can be enabled by setting the
optimizer_hoist_uncorrelated_equality_subqueries session setting to
true.

Fixes #83392
Informs #51820
Informs #93829
Informs #100855

Release note (performance improvement): Queries that have subqueries in
equality expressions are now more efficiently planned by the optimizer when
optimizer_hoist_uncorrelated_equality_subqueries is set to true.


Release justification: We're backporting this to 22.2, so we'll need it
to work in 23.1.0 as well.

Subqueries that are in equality expressions with a variable are now
hoisted. When these expressions exist in a filter, hoisting the subquery
can allow the main query to plan a lookup join, rather than an
inefficient full-table scan.

For example, consider the table and query:

    CREATE TABLE t (
      a INT,
      INDEX (a)
    );

    SELECT * FROM t WHERE a = (SELECT max(a) FROM t);

Prior to this commit, the query plan for this query required a full
table scan:

    select
     ├── columns: a:1
     ├── scan t@t_a_idx
     │    ├── columns: a:1
     │    └── constraint: /1/2: (/NULL - ]
     └── filters
          └── eq
               ├── a:1
               └── subquery
                    └── scalar-group-by
                         ├── columns: max:9
                         ├── scan t@t_a_idx,rev
                         │    ├── columns: a:5
                         │    ├── constraint: /5/6: (/NULL - ]
                         │    └── limit: 1(rev)
                         └── aggregations
                              └── const-agg [as=max:9, outer=(5)]
                                   └── a:5

By hoisting the subquery, the full table scan is replaced with a lookup
join:

    project
     ├── columns: a:1
     └── inner-join (lookup t@t_a_idx)
          ├── columns: a:1 max:9
          ├── key columns: [9] = [1]
          ├── scalar-group-by
          │    ├── columns: max:9
          │    ├── scan t@t_a_idx,rev
          │    │    ├── columns: a:5
          │    │    ├── constraint: /5/6: (/NULL - ]
          │    │    └── limit: 1(rev)
          │    └── aggregations
          │         └── const-agg [as=max:9, outer=(5)]
          │              └── a:5
          └── filters (true)

This hoisting is enabled by default, but can be disabled by setting the
`optimizer_hoist_uncorrelated_equality_subqueries` session setting to
`false`.

Fixes cockroachdb#83392
Informs cockroachdb#51820
Informs cockroachdb#93829
Informs cockroachdb#100855

Release note (performance improvement): Queries that have subqueries in
equality expressions are now more efficiently planned by the optimizer.
@mgartner mgartner requested a review from rytaft April 18, 2023 14:11
@mgartner mgartner requested a review from a team as a code owner April 18, 2023 14:11
@cockroach-teamcity
Copy link
Member

This change is Reviewable

@mgartner mgartner added the do-not-merge bors won't merge a PR with this label. label Apr 18, 2023
@mgartner
Copy link
Collaborator Author

Hold off on merging - need to default the setting to off.

@blathers-crl
Copy link

blathers-crl bot commented Apr 18, 2023

Thanks for opening a backport.

Please check the backport criteria before merging:

  • Patches should only be created for serious issues or test-only changes.
  • Patches should not break backwards-compatibility.
  • Patches should change as little code as possible.
  • Patches should not change on-disk formats or node communication protocols.
  • Patches should not add new functionality.
  • Patches must not add, edit, or otherwise modify cluster versions; or add version gates.
If some of the basic criteria cannot be satisfied, ensure that the exceptional criteria are satisfied within.
  • There is a high priority need for the functionality that cannot wait until the next release and is difficult to address in another way.
  • The new functionality is additive-only and only runs for clusters which have specifically “opted in” to it (e.g. by a cluster setting).
  • New code is protected by a conditional check that is trivial to verify and ensures that it only runs for opt-in clusters.
  • The PM and TL on the team that owns the changed code have signed off that the change obeys the above rules.

Add a brief release justification to the body of your PR to justify this backport.

Some other things to consider:

  • What did we do to ensure that a user that doesn’t know & care about this backport, has no idea that it happened?
  • Will this work in a cluster of mixed patch versions? Did we test that?
  • If a user upgrades a patch version, uses this feature, and then downgrades, what happens?

@mgartner mgartner closed this Apr 18, 2023
Copy link
Collaborator

@rytaft rytaft left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Do we really need this in the .0? Wouldn't .1 and beyond be good enough?

Reviewed 19 of 19 files at r1, all commit messages.
Reviewable status: :shipit: complete! 0 of 0 LGTMs obtained (waiting on @mgartner)

@mgartner
Copy link
Collaborator Author

Closed in favor of #101751.

@mgartner
Copy link
Collaborator Author

Do we really need this in the .0? Wouldn't .1 and beyond be good enough?

If we don't backport to 23.1.0 and a customer uses this setting in 22.2 and then upgrades to 23.1.0, then their query plans would be changed, and the error from the missing session setting could break their application.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
do-not-merge bors won't merge a PR with this label.
Projects
None yet
Development

Successfully merging this pull request may close these issues.

3 participants