-
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.
57836: sql: fix bug where bad mutation job state could block dropping tables r=lucy-zhang a=lucy-zhang Previously, while dropping a table, we would mark all the jobs associated with mutations on the table as `succeeded`, under the assumption that they were running. The job registry API prohibits this when the jobs are not `running` (or `pending`), so if a mutation was stuck on the table descriptor with a failed or nonexistent job, dropping the table would fail. This PR fixes the bug by checking the job state before attempting to update the job. It also fixes a related failure to drop a table caused by a valid mutation job not being in a `running` state. Fixes #57597. Release note (bug fix): Fixed a bug where prior schema changes on a table that failed and could not be fully reverted could prevent the table from being dropped. 58204: opt: use join filters to imply IS NOT NULL partial index predicates r=RaduBerinde a=mgartner #### opt: use join filters to imply IS NOT NULL partial index predicates This commit updates the reject null normalization rules so that: 1. `RejectNullsUnderJoinRight` matches `SemiJoin` and `AntiJoin`. 2. A `Scan` with a `col IS NOT NULL` predicate requests null rejection of `col`. In combination, these two changes allow partial indexes with `IS NOT NULL` predicates to be used in more cases. As an example, they can be used in JOINs where the ON condition implicitly implies the predicate: CREATE TABLE a (a INT PRIMARY KEY) CREATE TABLE b (b INT, INDEX (b) WHERE b IS NOT NULL) SELECT * FROM a JOIN b ON a = b As a another example, partial indexes with `IS NOT NULL` predicates can be used to satisfy foreign key checks. CREATE TABLE parent (id INT PRIMARY KEY) CREATE TABLE child ( id INT PRIMARY KEY, p_id INT, CONSTRAINT fk FOREIGN KEY (p_id) REFERENCES parent(id), INDEX (p_id) WHERE p_id IS NOT NULL ) DELETE FROM p WHERE id = 1 The `DELETE` requires a foreign key check to ensure that no existing rows in `child` have a matching `p_id`. Prior to this commit, the check performed a full table scan rather than using the partial index because its predicate was not implied. By pushing down the null-rejecting filter derived from the check's `child.p_id = parent.id` filter, the partial index can be used. Fixes #57841 Release justification: This improves performance for joins and foreign key checks on tables with partial indexes. Partial indexes are a new feature introduced in 20.2. Release note (performance improvement): Partial indexes with IS NOT NULL predicates can be used in cases where JOIN filters implicitly imply the predicate. This results in more efficient query plans for JOINs and foreign checks. Co-authored-by: Lucy Zhang <[email protected]> Co-authored-by: Marcus Gartner <[email protected]>
- Loading branch information
Showing
8 changed files
with
493 additions
and
67 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,125 @@ | ||
# LogicTest: local | ||
|
||
statement ok | ||
CREATE TABLE t ( | ||
a INT PRIMARY KEY, | ||
b INT, | ||
c STRING, | ||
FAMILY (a, b, c), | ||
INDEX b_partial (b) WHERE b > 10 | ||
) | ||
|
||
statement ok | ||
CREATE TABLE inv ( | ||
a INT PRIMARY KEY, | ||
b JSON, | ||
c STRING, | ||
INVERTED INDEX i (b) WHERE c IN ('foo', 'bar'), | ||
FAMILY (a, b, c) | ||
) | ||
|
||
# --------------------------------------------------------- | ||
# EXPLAIN | ||
# --------------------------------------------------------- | ||
|
||
# EXPLAIN output shows the partial index label on scans and joins on partial | ||
# indexes. | ||
query T | ||
EXPLAIN SELECT b FROM t WHERE b > 10 | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• scan | ||
missing stats | ||
table: t@b_partial (partial index) | ||
spans: FULL SCAN | ||
|
||
query T | ||
EXPLAIN SELECT t1.a FROM t t1 INNER LOOKUP JOIN t t2 ON t1.a = t2.b AND t2.b > 10 | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• lookup join | ||
│ table: t@b_partial (partial index) | ||
│ equality: (a) = (b) | ||
│ | ||
└── • scan | ||
missing stats | ||
table: t@primary | ||
spans: [/11 - ] | ||
|
||
query T | ||
EXPLAIN SELECT a FROM inv@i WHERE b @> '{"x": "y"}' AND c IN ('foo', 'bar') | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• scan | ||
missing stats | ||
table: inv@i (partial index) | ||
spans: 1 span | ||
|
||
query T | ||
EXPLAIN SELECT a FROM inv@i WHERE b @> '{"x": "y"}' AND c = 'foo' | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• filter | ||
│ filter: c = 'foo' | ||
│ | ||
└── • index join | ||
│ table: inv@primary | ||
│ | ||
└── • scan | ||
missing stats | ||
table: inv@i (partial index) | ||
spans: 1 span | ||
|
||
query T | ||
EXPLAIN SELECT * FROM inv@i WHERE b @> '{"x": "y"}' AND c IN ('foo', 'bar') | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• index join | ||
│ table: inv@primary | ||
│ | ||
└── • scan | ||
missing stats | ||
table: inv@i (partial index) | ||
spans: 1 span | ||
|
||
# --------------------------------------------------------- | ||
# JOIN | ||
# --------------------------------------------------------- | ||
|
||
statement ok | ||
CREATE TABLE a (a INT PRIMARY KEY); | ||
|
||
statement ok | ||
CREATE TABLE b (b INT, INDEX (b) WHERE b IS NOT NULL) | ||
|
||
# The partial index can be used because the ON condition implicitly implies the | ||
# partial index predicate, b IS NOT NULL. | ||
query T | ||
EXPLAIN SELECT * FROM a JOIN b ON a = b | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• merge join | ||
│ equality: (a) = (b) | ||
│ left cols are key | ||
│ | ||
├── • scan | ||
│ missing stats | ||
│ table: a@primary | ||
│ spans: FULL SCAN | ||
│ | ||
└── • scan | ||
missing stats | ||
table: b@b_b_idx (partial index) | ||
spans: FULL SCAN |
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
Oops, something went wrong.