-
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.
xform: derive implicit predicates from FK constraint for lookup join
Fixes #69617 When a unique constraint exists on a subset of the referenced columns in a foreign key constraint, the remaining columns in the constraint can be used to generate equijoin predicates which may enable more efficient use of an index on the lookup side of a lookup join. If the index is a multiregion index, a join predicate may be derived which could potentially eliminate reads of remote rows. Example: ``` CREATE TABLE accounts ( account_id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name STRING NOT NULL, crdb_region crdb_internal_region NOT NULL, UNIQUE INDEX acct_id_crdb_region_idx (account_id, crdb_region) ) LOCALITY GLOBAL; drop table if exists tweets; CREATE TABLE tweets ( account_id UUID NOT NULL, tweet_id UUID DEFAULT gen_random_uuid(), message STRING NOT NULL, crdb_region crdb_internal_region NOT NULL, PRIMARY KEY (crdb_region, account_id, tweet_id), -- The PK of accounts is a subset of the referenced columns in -- the FK constraint. FOREIGN KEY (account_id, crdb_region) REFERENCES accounts (account_id, crdb_region) ON DELETE CASCADE ON UPDATE CASCADE ) LOCALITY REGIONAL BY ROW as crdb_region; -- Join on account_id uses the uniqueness of accounts_pkey and the FK -- constraint to derive tweets.crdb_region = accounts.crdb_region EXPLAIN SELECT * FROM tweets INNER LOOKUP JOIN accounts@acct_id_crdb_region_idx USING (account_id) WHERE account_id = '6f781502-4936-43cc-b384-04e5cf292cc8'; ------------------------------------------------------------------------- distribution: local vectorized: true • lookup join │ table: accounts@accounts_pkey │ equality: (account_id) = (account_id) │ equality cols are key │ └── • lookup join │ table: accounts@acct_id_crdb_region_idx │ equality: (account_id, crdb_region) = (account_id,crdb_region) │ equality cols are key │ pred: account_id = '6f781502-4936-43cc-b384-04e5cf292cc8' │ └── • scan missing stats table: tweets@tweets_pkey spans: [/'ca'/'6f781502-4936-43cc-b384-04e5cf292cc8' - /'ca'/'6f781502-4936-43cc-b384-04e5cf292cc8'] [/'eu'/'6f781502-4936-43cc-b384-04e5cf292cc8' - /'eu'/'6f781502-4936-43cc-b384-04e5cf292cc8'] [/'us'/'6f781502-4936-43cc-b384-04e5cf292cc8' - /'us'/'6f781502-4936-43cc-b384-04e5cf292cc8'] ``` Release note (performance improvement): This patch enables more efficient lookup joins by deriving new join constraints when equijoin predicates exist on the column(s) of a unique constraint on one table which are a proper subset of the referencing columns of a foreign key constraint on the other table. If an index exists on those FK constraint referencing columns, equijoin predicates are derived between the PK and FK columns not currently bound by ON clause predicates.
- Loading branch information
Mark Sirek
committed
Nov 8, 2022
1 parent
1b4aa43
commit aaa6876
Showing
4 changed files
with
245 additions
and
1 deletion.
There are no files selected for viewing
88 changes: 88 additions & 0 deletions
88
pkg/ccl/logictestccl/testdata/logic_test/multi_region_foreign_key_lookup_join
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,88 @@ | ||
# tenant-cluster-setting-override-opt: allow-multi-region-abstractions-for-secondary-tenants | ||
# LogicTest: multiregion-9node-3region-3azs | ||
|
||
# Set the closed timestamp interval to be short to shorten the amount of time | ||
# we need to wait for the system config to propagate. | ||
statement ok | ||
SET CLUSTER SETTING kv.closed_timestamp.side_transport_interval = '10ms'; | ||
|
||
statement ok | ||
SET CLUSTER SETTING kv.closed_timestamp.target_duration = '10ms'; | ||
|
||
statement ok | ||
CREATE DATABASE multi_region_test_db PRIMARY REGION "ca-central-1" REGIONS "ap-southeast-2", "us-east-1"; | ||
|
||
statement ok | ||
USE multi_region_test_db | ||
|
||
statement ok | ||
CREATE TABLE parent ( | ||
p_id INT PRIMARY KEY, | ||
cr crdb_internal_region NOT NULL DEFAULT gateway_region()::crdb_internal_region, | ||
p_data string, | ||
p_int INT, | ||
p_text TEXT, | ||
p_json JSON, | ||
UNIQUE INDEX (p_data), | ||
INVERTED INDEX (p_int, p_json), | ||
INVERTED INDEX (p_int, p_text gin_trgm_ops) | ||
) LOCALITY REGIONAL BY ROW AS cr; | ||
|
||
statement ok | ||
CREATE TABLE child ( | ||
c_id INT PRIMARY KEY, | ||
c_p_id INT, | ||
cr crdb_internal_region NOT NULL DEFAULT gateway_region()::crdb_internal_region, | ||
c_data string, | ||
c_int INt, | ||
c_json JSON, | ||
FOREIGN KEY (c_p_id, cr) REFERENCES parent (p_id, cr) | ||
) LOCALITY REGIONAL BY ROW AS cr; | ||
|
||
# A 'cr = cr' condition should be derived for this join. | ||
query T | ||
EXPLAIN SELECT * | ||
FROM child | ||
INNER LOOKUP JOIN parent ON c_p_id = p_id | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• lookup join | ||
│ table: parent@parent_pkey | ||
│ equality: (cr, c_p_id) = (cr,p_id) | ||
│ equality cols are key | ||
│ | ||
└── • scan | ||
missing stats | ||
table: child@child_pkey | ||
spans: FULL SCAN | ||
|
||
# A 'cr = cr' condition should not be derived for this join. | ||
query T | ||
EXPLAIN SELECT 1 | ||
FROM child | ||
INNER LOOKUP JOIN parent ON p_data = c_data | ||
---- | ||
distribution: local | ||
vectorized: true | ||
· | ||
• render | ||
│ | ||
└── • lookup join | ||
│ table: parent@parent_p_data_key | ||
│ equality cols are key | ||
│ lookup condition: (cr = 'ap-southeast-2') AND (c_data = p_data) | ||
│ remote lookup condition: (cr IN ('ca-central-1', 'us-east-1')) AND (c_data = p_data) | ||
│ | ||
└── • scan | ||
missing stats | ||
table: child@child_pkey | ||
spans: FULL SCAN | ||
|
||
# Verify inverted index cases cannot derive a 'cr = cr' condition. Lookup join | ||
# is not possible. | ||
statement error could not produce a query plan conforming to the LOOKUP JOIN hint | ||
EXPLAIN SELECT * | ||
FROM child | ||
INNER LOOKUP JOIN parent ON p_int = c_int AND p_text LIKE '%foo%' |
7 changes: 7 additions & 0 deletions
7
pkg/ccl/logictestccl/tests/multiregion-9node-3region-3azs/generated_test.go
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
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