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

opt: the optimizer cost model should consider contention #79683

Closed
rytaft opened this issue Apr 8, 2022 · 4 comments · Fixed by #137984
Closed

opt: the optimizer cost model should consider contention #79683

rytaft opened this issue Apr 8, 2022 · 4 comments · Fixed by #137984
Labels
C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) O-support Would prevent or help troubleshoot a customer escalation - bugs, missing observability/tooling, docs P-3 Issues/test failures with no fix SLA T-sql-queries SQL Queries Team

Comments

@rytaft
Copy link
Collaborator

rytaft commented Apr 8, 2022

Currently, CockroachDB's optimizer tries to find the best plan for a query in isolation and doesn't concern itself with the possibility that reading more rows than needed could cause write conflicts. Consider the following example:

CREATE TABLE tab (
  a INT,
  b INT,
  INDEX (b)
);
INSERT INTO tab SELECT generate_series(1,500), 1;
INSERT INTO tab SELECT generate_series(501,1000), 2;
ANALYZE tab;
EXPLAIN UPDATE tab SET a = 2000 WHERE b = 1;
                                             info
-----------------------------------------------------------------------------------------------
  distribution: local
  vectorized: true

  • update
  │ table: tab
  │ set: a
  │ auto commit
  │
  └── • render
      │ estimated row count: 500
      │
      └── • filter
          │ estimated row count: 500
          │ filter: b = 1
          │
          └── • scan
                estimated row count: 1,000 (100% of the table; stats collected 2 seconds ago)
                table: tab@tab_pkey
                spans: FULL SCAN

The optimizer chooses a full scan of the primary index instead of using the index on b, since in isolation, this is less expensive than performing an index join with half the rows in the table. However, it means that any other query that wants to update rows where b = 2 will block, even though technically there is no conflict.

Ideally, the optimizer would almost never choose a full scan for mutation queries such as this one where a suitable index is available, due to the impact on contention.

Epic CRDB-37836

Jira issue: CRDB-14977

gz#11932

gz#18109

@rytaft rytaft added the C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) label Apr 8, 2022
@blathers-crl blathers-crl bot added the T-sql-queries SQL Queries Team label Apr 8, 2022
@cockroachdb cockroachdb deleted a comment from mari-crl May 25, 2022
@kenliu-crl
Copy link
Contributor

manually reviewed and updated

@nvanbenschoten
Copy link
Member

One suggestion for users that run into this issue is that index hints are supported for mutation statements. This makes it possible to control the index used during the initial row scan of a mutation, which can be important to minimize false contention in some cases.

For example, without a hint:

demo@127.0.0.1:26257/movr> EXPLAIN UPDATE tab SET a = 2000 WHERE b = 1;
                                              info
------------------------------------------------------------------------------------------------
  distribution: local
  vectorized: true

  • update
  │ table: tab
  │ set: a
  │ auto commit
  │
  └── • render
      │
      └── • filter
          │ estimated row count: 500
          │ filter: b = 1
          │
          └── • scan
                estimated row count: 1,000 (100% of the table; stats collected 36 seconds ago)
                table: tab@tab_pkey
                spans: FULL SCAN

With a hint:

demo@127.0.0.1:26257/movr> EXPLAIN UPDATE tab@tab_b_idx SET a = 2000 WHERE b = 1;
                                            info
---------------------------------------------------------------------------------------------
  distribution: local
  vectorized: true

  • update
  │ table: tab
  │ set: a
  │ auto commit
  │
  └── • render
      │
      └── • index join
          │ estimated row count: 500
          │ table: tab@tab_pkey
          │ locking strength: for update
          │
          └── • scan
                estimated row count: 500 (50% of the table; stats collected 39 seconds ago)
                table: tab@tab_b_idx
                spans: [/1 - /1]
                locking strength: for update

@mgartner
Copy link
Collaborator

@nvanbenschoten Do you know the reason for not propagating locking strength: for update to the full table scan in your first example above? We're considering using the locking strength of scans to penalize the cost of full table scans and scans with uncertain cardinality.

@nvanbenschoten
Copy link
Member

We don't push down the implicit row-level locking mode if the initial row scan of an UPDATE statement is not precise (e.g. contains a filter). This is meant to avoid false contention, though I think you could argue that it's an unprincipled rule that falls out of the fact that we don't support shared locks.

@mgartner mgartner moved this to Backlog (DO NOT ADD NEW ISSUES) in SQL Queries Jul 24, 2023
@rytaft rytaft moved this from Backlog (DO NOT ADD NEW ISSUES) to New Backlog in SQL Queries Jul 27, 2023
@rytaft rytaft moved this from New Backlog to 24.1 Release in SQL Queries Jul 27, 2023
@michae2 michae2 added the O-support Would prevent or help troubleshoot a customer escalation - bugs, missing observability/tooling, docs label Dec 4, 2023
@michae2 michae2 added the P-3 Issues/test failures with no fix SLA label Dec 21, 2023
@yuzefovich yuzefovich moved this from 24.1 Release to 24.2 Release in SQL Queries Feb 27, 2024
@mgartner mgartner moved this from 24.2 Release to 24.3 Release in SQL Queries Jun 20, 2024
@rytaft rytaft moved this from 25.1 Release to 24.3 Release in SQL Queries Sep 13, 2024
rytaft added a commit to rytaft/cockroach that referenced this issue Oct 7, 2024
Also update the error message to suggest adding a WHERE/LIMIT clause
with appropriate index.

Informs cockroachdb#79683

Release note (sql change): session setting `disallow_full_table_scans` and the
cluster setting `sql.defaults.disallow_full_table_scans.enabled` now default
to true.
@mgartner mgartner moved this from 24.3 Release to 25.1 Release in SQL Queries Oct 31, 2024
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. Note that a
full scan of a partial index may still be preferred by the optimizer,
unless AVOID_FULL_SCAN is used in combination with a specific partial
index via FORCE_INDEX=index_name. This hint is similar to NO_FULL_SCAN,
but will not error if a full scan cannot be avoided.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. Note that a
full scan of a partial index may still be preferred by the optimizer,
unless AVOID_FULL_SCAN is used in combination with a specific partial
index via FORCE_INDEX=index_name. This hint is similar to NO_FULL_SCAN,
but will not error if a full scan cannot be avoided.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. Note that a
full scan of a partial index may still be preferred by the optimizer,
unless AVOID_FULL_SCAN is used in combination with a specific partial
index via FORCE_INDEX=index_name. This hint is similar to NO_FULL_SCAN,
but will not error if a full scan cannot be avoided.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 19, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 20, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 20, 2024
Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. Note that a
full scan of a partial index may still be preferred by the optimizer,
unless AVOID_FULL_SCAN is used in combination with a specific partial
index via FORCE_INDEX=index_name. This hint is similar to NO_FULL_SCAN,
but will not error if a full scan cannot be avoided.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 20, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 20, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 20, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 24, 2024
Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. Note that a
full scan of a partial index may still be preferred by the optimizer,
unless AVOID_FULL_SCAN is used in combination with a specific partial
index via FORCE_INDEX=index_name. This hint is similar to NO_FULL_SCAN,
but will not error if a full scan cannot be avoided.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 24, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to memo.Cost with a new type
memo.CostFlags, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new FullScanPenalty cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new CostFlags type also includes a flag for HugeCostPenalty, which
must be set for plans with "hugeCost". This ensures that existing
hints that use hugeCost still work if some other cost flags are set,
since HugeCostPenalty takes precedence over other cost flags.

This new CostFlags field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using "hugeCost" to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than hugeCost due to
loss of floating point precision.

Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. This hint is
similar to NO_FULL_SCAN, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the NO_FULL_SCAN and
AVOID_FULL_SCAN hints, but if the user has explicitly forced the
partial index via FORCE_INDEX=index_name, we do consider it a full
scan.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to memo.Cost with a new type
memo.CostFlags, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new FullScanPenalty cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new CostFlags type also includes a flag for HugeCostPenalty, which
must be set for plans with "hugeCost". This ensures that existing
hints that use hugeCost still work if some other cost flags are set,
since HugeCostPenalty takes precedence over other cost flags.

This new CostFlags field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using "hugeCost" to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than hugeCost due to
loss of floating point precision.

Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. This hint is
similar to NO_FULL_SCAN, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the NO_FULL_SCAN and
AVOID_FULL_SCAN hints, but if the user has explicitly forced the
partial index via FORCE_INDEX=index_name, we do consider it a full
scan.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to memo.Cost with a new type
memo.CostFlags, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new FullScanPenalty cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new CostFlags type also includes a flag for HugeCostPenalty, which
must be set for plans with "hugeCost". This ensures that existing
hints that use hugeCost still work if some other cost flags are set,
since HugeCostPenalty takes precedence over other cost flags.

This new CostFlags field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using "hugeCost" to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than hugeCost due to
loss of floating point precision.

Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. This hint is
similar to NO_FULL_SCAN, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the NO_FULL_SCAN and
AVOID_FULL_SCAN hints, but if the user has explicitly forced the
partial index via FORCE_INDEX=index_name, we do consider it a full
scan.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 25, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 26, 2024
Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to memo.Cost with a new type
memo.CostFlags, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new FullScanPenalty cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new CostFlags type also includes a flag for HugeCostPenalty, which
must be set for plans with "hugeCost". This ensures that existing
hints that use hugeCost still work if some other cost flags are set,
since HugeCostPenalty takes precedence over other cost flags.

This new CostFlags field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using "hugeCost" to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than hugeCost due to
loss of floating point precision.

Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. This hint is
similar to NO_FULL_SCAN, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the NO_FULL_SCAN and
AVOID_FULL_SCAN hints, but if the user has explicitly forced the
partial index via FORCE_INDEX=index_name, we do consider it a full
scan.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 26, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 26, 2024
Fixes cockroachdb#79683

Release note (sql change): Added a new session setting
avoid_full_table_scans_in_mutations, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.
rytaft added a commit to rytaft/cockroach that referenced this issue Dec 28, 2024
Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to memo.Cost with a new type
memo.CostFlags, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new FullScanPenalty cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new CostFlags type also includes a flag for HugeCostPenalty, which
must be set for plans with "hugeCost". This ensures that existing
hints that use hugeCost still work if some other cost flags are set,
since HugeCostPenalty takes precedence over other cost flags.

This new CostFlags field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using "hugeCost" to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than hugeCost due to
loss of floating point precision.

Informs cockroachdb#79683

Release note (sql change): Added support for a new index hint,
AVOID_FULL_SCAN, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, SELECT * FROM table_name@{AVOID_FULL_SCAN};. This hint is
similar to NO_FULL_SCAN, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the NO_FULL_SCAN and
AVOID_FULL_SCAN hints, but if the user has explicitly forced the
partial index via FORCE_INDEX=index_name, we do consider it a full
scan.
craig bot pushed a commit that referenced this issue Dec 28, 2024
137984: sql, opt: avoid full scans in mutation queries with cost flags r=rytaft a=rytaft

**opt: convert `memo.Cost` to a struct with `CostFlags`**

This is a mechanical change that will set up the ability to use
`CostFlags` in a future commit.

Release note: None

**opt,sql: support hint to avoid full scan**

Added a hint to avoid full scans (see release note below for details).
To support this change, added a field to `memo.Cost` with a new type
`memo.CostFlags`, which contains a number of boolean flags and supports
"multi-dimensional costing". This allows the optimizer to compare plans
based on the flags set in addition to the single-dimensional float64
cost. For example, plans with the new `FullScanPenalty` cost flag enabled
will always be more expensive than plans without any cost flags, even
if the base float64 cost is lower.

The new `CostFlags` type also includes a flag for `HugeCostPenalty`, which
must be set for plans with `hugeCost`. This ensures that existing
hints that use `hugeCost` still work if some other cost flags are set,
since `HugeCostPenalty` takes precedence over other cost flags.

This new `CostFlags` field is needed to support hints that do not cause an
error if the optimizer cannot find a plan complying with the hint. This
is needed because the previous approach of simply using `hugeCost` to
avoid certain plans meant that if such plans were unavoidable, we could
not effectively compare plans with cost greater than `hugeCost` due to
loss of floating point precision.

Informs #79683

Release note (sql change): Added support for a new index hint,
`AVOID_FULL_SCAN`, which will prevent the optimizer from planning a
full scan for the specified table if any other plan is possible. The
hint can be used in the same way as other existing index hints. For
example, `SELECT * FROM table_name@{AVOID_FULL_SCAN};`. This hint is
similar to `NO_FULL_SCAN`, but will not error if a full scan cannot be
avoided. Note that normally a full scan of a partial index would not
be considered a "full scan" for the purposes of the `NO_FULL_SCAN` and
`AVOID_FULL_SCAN` hints, but if the user has explicitly forced the
partial index via `FORCE_INDEX=index_name`, we do consider it a full
scan.

**sql,opt: add setting `avoid_full_table_scans_in_mutations`**

Fixes #79683

Release note (sql change): Added a new session setting
`avoid_full_table_scans_in_mutations`, which when set to true, causes
the optimizer to avoid planning full table scans for mutation queries
if any other plan is possible. It now defaults to true.

**opt: remove a stale comment above `optbuilder.buildScan`**

Removed a comment that references a function parameter that no longer
exists.

Release note: None

Co-authored-by: Rebecca Taft <becca@cockroachlabs.com>
@craig craig bot closed this as completed in ce98c91 Dec 28, 2024
@github-project-automation github-project-automation bot moved this from 25.1 Release to Done in SQL Queries Dec 28, 2024
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) O-support Would prevent or help troubleshoot a customer escalation - bugs, missing observability/tooling, docs P-3 Issues/test failures with no fix SLA T-sql-queries SQL Queries Team
Projects
Status: Done
6 participants