From 89aadab4d2667bc96043fc0c2fd11447e495c31b Mon Sep 17 00:00:00 2001 From: Mark Sirek Date: Fri, 14 Jan 2022 03:15:36 -0800 Subject: [PATCH] opt: locality optimized scan for queries with a LIMIT clause This commit adds locality optimized scan support for queries which place a hard limit on the number of rows returned via the LIMIT clause. This optimization benefits tables with REGIONAL BY ROW locality by splitting the spans accessed into a local spans set and a remote spans set, combined via a UNION ALL operation where each branch of the UNION ALL has the same hard limit as the original SELECT query block. If the limit is reached by scanning just the local spans, then latency is improved. The optimization is not applied if the LIMIT is more than the KV batch size of 100000 rows or if the number of spans in the scan exceeds 10000. This commit also adds an improvement to span merging to avoid merging local spans with remote spans in order to maximize the number of queries that can utilize locality optimized scan. Informs #64862 Release note (Performance Improvement): Queries with a LIMIT clause applied against a single table, either explicitly written, or implicit such as in an uncorrelated EXISTS subquery, now scan that table with improved latency if the table is defined with LOCALITY REGIONAL BY ROW and the number of qualified rows residing in the local region is less than or equal to the hard limit (sum of the LIMIT clause and optional OFFSET clause values). This optimization is only applied if the hard limit is 100000 or less. --- .../logic_test/regional_by_row_query_behavior | 1147 +++++++++++++++++ pkg/sql/opt/constraint/constraint.go | 54 +- pkg/sql/opt/constraint/key.go | 32 + pkg/sql/opt/table_meta.go | 6 + pkg/sql/opt/xform/scan_funcs.go | 109 +- pkg/sql/opt/xform/testdata/rules/scan | 27 +- pkg/sql/types/types.go | 9 + 7 files changed, 1355 insertions(+), 29 deletions(-) diff --git a/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row_query_behavior b/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row_query_behavior index 5d158dbb0b03..aae3ae591d2c 100644 --- a/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row_query_behavior +++ b/pkg/ccl/logictestccl/testdata/logic_test/regional_by_row_query_behavior @@ -2259,3 +2259,1150 @@ query I SELECT * FROM t73024 ---- 100 + +############################################## +# Locality optimized scans with LIMIT clause # +############################################## +statement ok +USE multi_region_test_db + +# LIMIT clause enables locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table LIMIT 1] OFFSET 2 +---- +· +• union all +│ limit: 1 +│ +├── • scan +│ missing stats +│ table: regional_by_row_table@regional_by_row_table_pkey +│ spans: [/'ap-southeast-2' - /'ap-southeast-2'] +│ limit: 1 +│ +└── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_pkey + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 1 + +query IIIIT +SELECT pk, pk2, a, b, crdb_region FROM regional_by_row_table LIMIT 1 +---- +1 1 2 3 ap-southeast-2 + +# LIMIT clause plus PK lookup doesn't create limited scans. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table WHERE pk=1 LIMIT 1] OFFSET 2 +---- +· +• union all +│ limit: 1 +│ +├── • scan +│ missing stats +│ table: regional_by_row_table@regional_by_row_table_pkey +│ spans: [/'ap-southeast-2'/1 - /'ap-southeast-2'/1] +│ +└── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_pkey + spans: [/'ca-central-1'/1 - /'ca-central-1'/1] [/'us-east-1'/1 - /'us-east-1'/1] + +query IIII +SELECT pk, pk2, a, b FROM regional_by_row_table WHERE pk=1 LIMIT 1 +---- +1 1 2 3 + +# Keyset pagination +# LIMIT clause + PK constraint and ORDER BY allows locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table WHERE pk > 3 ORDER BY PK LIMIT 1] OFFSET 2 +---- +· +• limit +│ count: 1 +│ +└── • union all + │ + ├── • union all + │ │ + │ ├── • scan + │ │ missing stats + │ │ table: regional_by_row_table@regional_by_row_table_pkey + │ │ spans: [/'ap-southeast-2'/4 - /'ap-southeast-2'] + │ │ limit: 1 + │ │ + │ └── • scan + │ missing stats + │ table: regional_by_row_table@regional_by_row_table_pkey + │ spans: [/'ca-central-1'/4 - /'ca-central-1'] + │ limit: 1 + │ + └── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_pkey + spans: [/'us-east-1'/4 - /'us-east-1'] + limit: 1 + +query IIIIT +SELECT pk, pk2, a, b, crdb_region FROM regional_by_row_table WHERE pk > 3 ORDER BY PK LIMIT 1 +---- +4 4 5 6 ap-southeast-2 + +# LIMIT clause and ORDER BY with no PK constraint allows locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table ORDER BY PK LIMIT 2] OFFSET 2 +---- +· +• limit +│ count: 2 +│ +└── • union all + │ + ├── • union all + │ │ + │ ├── • scan + │ │ missing stats + │ │ table: regional_by_row_table@regional_by_row_table_pkey + │ │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ │ limit: 2 + │ │ + │ └── • scan + │ missing stats + │ table: regional_by_row_table@regional_by_row_table_pkey + │ spans: [/'ca-central-1' - /'ca-central-1'] + │ limit: 2 + │ + └── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_pkey + spans: [/'us-east-1' - /'us-east-1'] + limit: 2 + +query IIIIT +SELECT pk, pk2, a, b, crdb_region FROM regional_by_row_table ORDER BY PK LIMIT 2 +---- +1 1 2 3 ap-southeast-2 +4 4 5 6 ap-southeast-2 + +# LIMIT and OFFSET clause enables locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table LIMIT 1 OFFSET 2] OFFSET 2 +---- +· +• limit +│ offset: 2 +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table@regional_by_row_table_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_pkey + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +## Need to scan to remote region. Only 2 rows in local region. +query IIIIT +SELECT pk, pk2, a, b, crdb_region FROM regional_by_row_table LIMIT 1 OFFSET 2 +---- +6 6 5 -5 ca-central-1 + +# LIMIT in IN subquery enables locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table a WHERE + pk IN (SELECT pk FROM regional_by_row_table b LIMIT 3)] OFFSET 2 +---- +· +• lookup join +│ table: regional_by_row_table@regional_by_row_table_pkey +│ equality cols are key +│ lookup condition: (pk = pk) AND (crdb_region = 'ap-southeast-2') +│ remote lookup condition: (pk = pk) AND (crdb_region IN ('ca-central-1', 'us-east-1')) +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table@regional_by_row_table_a_idx + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table@regional_by_row_table_a_idx + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIII +SELECT pk, pk2, a, b FROM regional_by_row_table a + WHERE pk IN (SELECT pk FROM regional_by_row_table b LIMIT 3) +---- +1 1 2 3 +4 4 5 6 +6 6 5 -5 + +# Correlated semijoin with LIMIT in outer query block should not enable locality optimized scan. +query T +SELECT * FROM [EXPLAIN (DISTSQL) SELECT * FROM child WHERE EXISTS (SELECT * FROM parent WHERE p_id = c_p_id) LIMIT 3] OFFSET 2 +---- +· +• limit +│ count: 3 +│ +└── • lookup join (semi) + │ table: parent@parent_pkey + │ equality cols are key + │ lookup condition: (p_id = c_p_id) AND (crdb_region = 'ap-southeast-2') + │ remote lookup condition: (p_id = c_p_id) AND (crdb_region IN ('ca-central-1', 'us-east-1')) + │ + └── • scan + missing stats + table: child@child_pkey + spans: FULL SCAN +· +Diagram: https://cockroachdb.github.io/distsqlplan/decode.html#eJzkVF1ro1AQfd9fMcxLkuWW-JWkXAhYWsNaTNKNwhYaCa4OXXeN1_UDUkL--6IGqqU1Kd23vumdOTOHcw6zx-xvhBxtwzKuHfgKs9VyDg_G_Z11ZS6gf2Pajv3dGkC7wf8VRgH8-GasDDDuyx7otzsSL6U4P7YkmzCAKfib8mMAljk3HVBdWM5mtuGAggxjEdDC21KG_AFlZKghwwm6DJNU-JRlIi1L-6rRDHbIJYZhnBR5-ewy9EVKyPeYh3lEyNHxfka0Ii-gdCghw4ByL4yq8RV7PUnDrZc-IcNrERXbOOPgb8KAHWkiQzvxyteL4RrX692ltMahhO6BoSjy58VZ7j0ScvnAzid3K8L4yE1tc3OeEuJgGTMHbGNuwu3SXCDDWs4GZ0uIP0UCv0UYg4g59HUVpqArA7ha3EBf12AKu54m9TjnuixJ0mgyQIYr2oqcIDqJLs3f9S6beAa7nt8aWE5cFjkHXWZ66aIVbsMc1DdFUt4U6VmbIhZpQCkFLWHcwysyLsSFSIbjtoKnOKgtDvL5KZI_lKJmiI6J8t-TqBNEG4nSPm-ilPPdVP6Dm7WBF2c6eIJcw8HR53XwxOFcUZaIOKMXt-H1yVJ5Myh4pPrAZKJIfbpLhV-tqX-XFa56CCjL66pc_5hxXSoJNsFyJ1hpgeWXYKUTPOnerHaCtW6w9hHao07wuHvz-F2b3cOXfwEAAP__qPCjkw== + +query II rowsort +SELECT * FROM child WHERE EXISTS (SELECT * FROM parent WHERE p_id = c_p_id) LIMIT 3 +---- +20 20 +10 10 +30 30 + +# Uncorrelated semijoin with LIMIT can't enable locality optimized scan in the outer query block yet. +# TODO(msirek) Push the LIMIT into the outer table scan via issue #75301. +query T +SELECT * FROM [EXPLAIN SELECT * FROM child WHERE EXISTS (SELECT * FROM parent) LIMIT 3] OFFSET 2 +---- +· +• root +│ +├── • limit +│ │ count: 3 +│ │ +│ └── • filter +│ │ filter: @S1 +│ │ +│ └── • scan +│ missing stats +│ table: child@child_pkey +│ spans: [/'ap-southeast-2' - /'ap-southeast-2'] [/'ca-central-1' - /'us-east-1'] +│ +└── • subquery + │ id: @S1 + │ original sql: EXISTS (SELECT * FROM parent) + │ exec mode: exists + │ + └── • union all + │ limit: 1 + │ + ├── • scan + │ missing stats + │ table: parent@parent_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 1 + │ + └── • scan + missing stats + table: parent@parent_pkey + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 1 + +query II +SELECT * FROM child WHERE EXISTS (SELECT * FROM parent) LIMIT 3 +---- +10 10 +20 20 +30 30 + +# Uncorrelated antijoin with LIMIT can't enable locality optimized scan in the outer query block yet. +# TODO(msirek) Push the LIMIT into the outer table scan via issue #75301. +query T +SELECT * FROM [EXPLAIN SELECT * FROM child WHERE NOT EXISTS (SELECT * FROM parent) LIMIT 3] OFFSET 2 +---- +· +• root +│ +├── • limit +│ │ count: 3 +│ │ +│ └── • filter +│ │ filter: NOT @S1 +│ │ +│ └── • scan +│ missing stats +│ table: child@child_pkey +│ spans: [/'ap-southeast-2' - /'ap-southeast-2'] [/'ca-central-1' - /'us-east-1'] +│ +└── • subquery + │ id: @S1 + │ original sql: EXISTS (SELECT * FROM parent) + │ exec mode: exists + │ + └── • union all + │ limit: 1 + │ + ├── • scan + │ missing stats + │ table: parent@parent_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 1 + │ + └── • scan + missing stats + table: parent@parent_pkey + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 1 + +query II +SELECT * FROM child WHERE NOT EXISTS (SELECT * FROM parent) LIMIT 3 +---- + +# LIMIT in IN subquery of REGIONAL BY ROW AS table enables locality optimized +# scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as a WHERE + pk IN (SELECT pk FROM regional_by_row_table_as b LIMIT 3)] OFFSET 2 +---- +· +• lookup join +│ table: regional_by_row_table_as@regional_by_row_table_as_pkey +│ equality cols are key +│ lookup condition: (pk = pk) AND (crdb_region_col = 'ap-southeast-2') +│ remote lookup condition: (pk = pk) AND (crdb_region_col IN ('ca-central-1', 'us-east-1')) +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as@regional_by_row_table_as_a_idx + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as@regional_by_row_table_as_a_idx + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIIT +SELECT pk, a, b, crdb_region_col FROM regional_by_row_table_as a + WHERE pk IN (SELECT pk FROM regional_by_row_table_as b LIMIT 3) +---- +20 NULL NULL ap-southeast-2 +30 1 1 ap-southeast-2 +1 NULL NULL us-east-1 + +# Correlated EXISTS with LIMIT in subquery should not build a UNION ALL because LIMIT is a per-group attribute +# when there's correlation. +query T +SELECT * FROM [EXPLAIN SELECT * FROM child WHERE EXISTS (SELECT * FROM parent WHERE p_id = c_p_id LIMIT 3)] OFFSET 2 +---- +· +• hash join (semi) +│ equality: (c_p_id) = (p_id) +│ right cols are key +│ +├── • scan +│ missing stats +│ table: child@child_pkey +│ spans: FULL SCAN +│ +└── • scan + missing stats + table: parent@parent_pkey + spans: FULL SCAN + +query II +SELECT * FROM child WHERE EXISTS (SELECT * FROM parent WHERE p_id = c_p_id LIMIT 3) +---- +10 10 +30 30 +20 20 + +# Create an explicit crdb_internal_region check constraint. +statement ok +CREATE TABLE regional_by_row_table_as1 ( + pk int PRIMARY KEY, + a int, + b int, + crdb_region_col1 crdb_internal_region NOT NULL AS ( + CASE + WHEN pk <= 10 THEN 'ca-central-1' + ELSE 'us-east-1' + END + ) VIRTUAL CHECK(crdb_region_col1 BETWEEN 'ap-southeast-2' AND 'us-east-1'), + crdb_region_col crdb_internal_region NOT NULL AS ( + CASE + WHEN pk <= 1 THEN 'ca-central-1' + ELSE 'us-east-1' + END + ) VIRTUAL, + INDEX (a), + UNIQUE (b), + FAMILY (pk, a, b) +) LOCALITY REGIONAL BY ROW AS crdb_region_col1 + +statement ok +INSERT INTO regional_by_row_table_as1 (pk) VALUES (1), (2), (3), (10), (20) + +# An extra crdb_region check constraint should still allow locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as1 LIMIT 3] OFFSET 2 +---- +· +• render +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as1@regional_by_row_table_as1_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as1@regional_by_row_table_as1_pkey + spans: [/'ca-central-1' - /'ca-central-1'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIITT +SELECT pk, a, b, crdb_region_col, crdb_region_col1 FROM regional_by_row_table_as1 LIMIT 3 +---- +1 NULL NULL ca-central-1 ca-central-1 +2 NULL NULL us-east-1 ca-central-1 +3 NULL NULL us-east-1 ca-central-1 + +# LIMIT in IN subquery of REGIONAL BY ROW AS table enables locality optimized +# scan. +query T nodeidx=4 +USE multi_region_test_db; SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as1 a + WHERE pk IN (SELECT pk FROM regional_by_row_table_as1 b LIMIT 3)] OFFSET 2 +---- +· +• render +│ +└── • lookup join + │ table: regional_by_row_table_as1@regional_by_row_table_as1_pkey + │ equality cols are key + │ lookup condition: (pk = pk) AND (crdb_region_col1 = 'ca-central-1') + │ remote lookup condition: (pk = pk) AND (crdb_region_col1 IN ('ap-southeast-2', 'us-east-1')) + │ + └── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as1@regional_by_row_table_as1_a_idx + │ spans: [/'ca-central-1' - /'ca-central-1'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as1@regional_by_row_table_as1_a_idx + spans: [/'ap-southeast-2' - /'ap-southeast-2'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIITT nodeidx=4 +USE multi_region_test_db; SELECT pk, a, b, crdb_region_col, crdb_region_col1 FROM regional_by_row_table_as1 a + WHERE pk IN (SELECT pk FROM regional_by_row_table_as1 b LIMIT 3) +---- +1 NULL NULL ca-central-1 ca-central-1 +2 NULL NULL us-east-1 ca-central-1 +3 NULL NULL us-east-1 ca-central-1 + +# Create an explicit crdb_internal_region check constraint that is an IN +# expression, the same as the implicit constraint on the partitioning column. +statement ok +CREATE TABLE regional_by_row_table_as2 ( + pk int PRIMARY KEY, + a int, + b int, + crdb_region_col1 crdb_internal_region NOT NULL CHECK(crdb_region_col1 IN ('ca-central-1', 'us-east-1')), + crdb_region_col crdb_internal_region AS ( + CASE + WHEN pk <= 10 THEN 'ca-central-1' + ELSE 'us-east-1' + END + ) VIRTUAL, + INDEX (a), + UNIQUE (b), + FAMILY (pk, a, b) +) LOCALITY REGIONAL BY ROW AS crdb_region_col + +statement ok +INSERT INTO regional_by_row_table_as2 (pk, crdb_region_col1) VALUES (1, 'ca-central-1'), (2, 'ca-central-1'), + (3, 'us-east-1'), (10, 'us-east-1'), (20, 'us-east-1') + +# An extra IN predicate CHECK constraint should not confuse the internal logic +# which checks the implicit IN predicate on the real crdb_region PK column. +query T nodeidx=5 +USE multi_region_test_db; SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as2 LIMIT 3] OFFSET 2 +---- +· +• render +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + │ spans: [/'ca-central-1' - /'ca-central-1'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + spans: [/'ap-southeast-2' - /'ap-southeast-2'] [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIITT nodeidx=5 +USE multi_region_test_db; SELECT pk, a, b, crdb_region_col, crdb_region_col1 FROM regional_by_row_table_as2 LIMIT 3 +---- +1 NULL NULL ca-central-1 ca-central-1 +2 NULL NULL ca-central-1 ca-central-1 +3 NULL NULL ca-central-1 us-east-1 + +# Adding a constraint still allows locality optimized scan. +query T nodeidx=5 +USE multi_region_test_db; SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as2 WHERE pk <> 4 LIMIT 3] OFFSET 2 +---- +· +• render +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + │ spans: [/'ca-central-1' - /'ca-central-1'/3] [/'ca-central-1'/5 - /'ca-central-1'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + spans: [/'ap-southeast-2' - /'ap-southeast-2'/3] [/'ap-southeast-2'/5 - /'ap-southeast-2'] [/'us-east-1' - /'us-east-1'/3] [/'us-east-1'/5 - /'us-east-1'] + limit: 3 + +query IIITT nodeidx=5 +USE multi_region_test_db; SELECT pk, a, b, crdb_region_col, crdb_region_col1 + FROM regional_by_row_table_as2 WHERE pk <> 4 LIMIT 3 +---- +1 NULL NULL ca-central-1 ca-central-1 +2 NULL NULL ca-central-1 ca-central-1 +3 NULL NULL ca-central-1 us-east-1 + +# Adding a filter disallows locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as2 WHERE pk <> 4 AND a > 1 LIMIT 3] OFFSET 2 +---- +· +• render +│ +└── • limit + │ count: 3 + │ + └── • filter + │ filter: (pk != 4) AND (a > 1) + │ + └── • scan + missing stats + table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + spans: FULL SCAN + +# Locality optimized scan on an index with LIMIT +query T nodeidx=5 +USE multi_region_test_db; +SELECT * FROM +[EXPLAIN(VERBOSE) SELECT * FROM regional_by_row_table_as2@regional_by_row_table_as2_a_idx LIMIT 3] OFFSET 2 +---- +· +• render +│ columns: (pk, a, b, crdb_region_col1, crdb_region_col) +│ estimated row count: 3 (missing stats) +│ render crdb_region_col: CASE WHEN pk <= 10 THEN 'ca-central-1' ELSE 'us-east-1' END +│ render pk: pk +│ render a: a +│ render b: b +│ render crdb_region_col1: crdb_region_col1 +│ +└── • index join + │ columns: (pk, a, b, crdb_region_col1) + │ estimated row count: 3 (missing stats) + │ table: regional_by_row_table_as2@regional_by_row_table_as2_pkey + │ key columns: crdb_region_col, pk + │ + └── • union all + │ columns: (pk, a, crdb_region_col) + │ estimated row count: 3 (missing stats) + │ limit: 3 + │ + ├── • scan + │ columns: (pk, a, crdb_region_col) + │ estimated row count: 3 (missing stats) + │ table: regional_by_row_table_as2@regional_by_row_table_as2_a_idx + │ spans: /"\x80"-/"\x80"/PrefixEnd + │ limit: 3 + │ + └── • scan + columns: (pk, a, crdb_region_col) + estimated row count: 3 (missing stats) + table: regional_by_row_table_as2@regional_by_row_table_as2_a_idx + spans: /"@"-/"@"/PrefixEnd /"\xc0"-/"\xc0"/PrefixEnd + limit: 3 + +query IIITT nodeidx=5 +USE multi_region_test_db; SELECT pk, a, b, crdb_region_col, crdb_region_col1 + FROM regional_by_row_table_as2@regional_by_row_table_as2_a_idx LIMIT 3 +---- +1 NULL NULL ca-central-1 ca-central-1 +2 NULL NULL ca-central-1 ca-central-1 +3 NULL NULL ca-central-1 us-east-1 + +# Create 2 explicit crdb_internal_region check constraints that are IN +# expressions, the same as the implicit constraint on the partitioning column. +# This table also has no PK. +statement ok +CREATE TABLE regional_by_row_table_as3 ( + pk int, + a int, + b int, + crdb_region_col1 crdb_internal_region NOT NULL AS ( + CASE + WHEN pk <= 1 THEN 'ca-central-1' + ELSE 'us-east-1' + END + ) STORED CHECK(crdb_region_col1 IN ('ca-central-1', 'us-east-1')), + crdb_region_col crdb_internal_region NOT NULL AS ( + CASE + WHEN pk <= 3 THEN 'ap-southeast-2' + ELSE 'us-east-1' + END + ) STORED CHECK(crdb_region_col IN ('ap-southeast-2', 'us-east-1')), + INDEX (a), + UNIQUE (b), + FAMILY (pk, a, b) +) LOCALITY REGIONAL BY ROW AS crdb_region_col + +statement ok +INSERT INTO regional_by_row_table_as3 (pk) VALUES (1), (2), (3), (10), (20) + +# The explicit check constraint on crdb_region_col which checks only 2 regions +# is used in the UNION ALL. It does not matter whether the implicit check +# constraint or explicit one is used because we know no rows can exist +# that don't satisfy both IN predicate checks. This edge case likely won't +# be created by a real user, but if it is, it will behave correctly. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as3@regional_by_row_table_as3_a_idx LIMIT 3] OFFSET 2 +---- +· +• index join +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as3@regional_by_row_table_as3_a_idx + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_a_idx + spans: [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIITT +SELECT * FROM regional_by_row_table_as3@regional_by_row_table_as3_a_idx LIMIT 3 +---- +1 NULL NULL ca-central-1 ap-southeast-2 +2 NULL NULL us-east-1 ap-southeast-2 +3 NULL NULL us-east-1 ap-southeast-2 + +# LIMIT in NOT IN subquery of REGIONAL BY ROW AS table enables locality +# optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as3 a WHERE + pk NOT IN (SELECT pk FROM regional_by_row_table_as3 b LIMIT 3)] OFFSET 2 +---- +· +• cross join (anti) +│ pred: (pk = pk) IS NOT false +│ +├── • scan +│ missing stats +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ spans: FULL SCAN +│ +└── • union all + │ limit: 3 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 3 + │ + └── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + spans: [/'us-east-1' - /'us-east-1'] + limit: 3 + +query IIITT +SELECT * FROM regional_by_row_table_as3 a WHERE pk NOT IN (SELECT pk FROM regional_by_row_table_as3 b LIMIT 3) +---- +10 NULL NULL us-east-1 us-east-1 +20 NULL NULL us-east-1 us-east-1 + +# Max KV batch size allows locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as3 a WHERE + pk NOT IN (SELECT pk FROM regional_by_row_table_as3 b LIMIT 100000)] OFFSET 2 +---- +· +• cross join (anti) +│ pred: (pk = pk) IS NOT false +│ +├── • scan +│ missing stats +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ spans: FULL SCAN +│ +└── • union all + │ limit: 100000 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 100000 + │ + └── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + spans: [/'us-east-1' - /'us-east-1'] + limit: 100000 + +query IIITT +SELECT * FROM regional_by_row_table_as3 a WHERE +pk NOT IN (SELECT pk FROM regional_by_row_table_as3 b LIMIT 100000) +---- + +# Max KV batch size + 1 does not allow locality optimized scan. +query T +SELECT * FROM [EXPLAIN SELECT * FROM regional_by_row_table_as3 a WHERE + pk NOT IN (SELECT pk FROM regional_by_row_table_as3 b LIMIT 100001)] OFFSET 2 +---- +· +• cross join (anti) +│ pred: (pk = pk) IS NOT false +│ +├── • scan +│ missing stats +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ spans: FULL SCAN +│ +└── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + spans: LIMITED SCAN + limit: 100001 + +# Locality optimized scan in a derived table +query T +SELECT * FROM [EXPLAIN SELECT * FROM (SELECT * FROM regional_by_row_table_as3 LIMIT 1) a, regional_by_row_table_as3 b + WHERE a.pk = b.pk] OFFSET 2 +---- +· +• hash join +│ equality: (pk) = (pk) +│ right cols are key +│ +├── • scan +│ missing stats +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ spans: FULL SCAN +│ +└── • union all + │ limit: 1 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 1 + │ + └── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + spans: [/'us-east-1' - /'us-east-1'] + limit: 1 + +query IIITTIIITT +SELECT * FROM (SELECT * FROM regional_by_row_table_as3 LIMIT 1) a, regional_by_row_table_as3 b WHERE a.pk = b.pk +---- +1 NULL NULL ca-central-1 ap-southeast-2 1 NULL NULL ca-central-1 ap-southeast-2 + +# Locality optimized scan in a scalar subquery and main query +query T +SELECT * FROM [EXPLAIN SELECT (SELECT pk FROM regional_by_row_table_as3 LIMIT 1), b.* FROM regional_by_row_table_as3 b + LIMIT 3] OFFSET 2 +---- +· +• root +│ +├── • render +│ │ +│ └── • union all +│ │ limit: 3 +│ │ +│ ├── • scan +│ │ missing stats +│ │ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] +│ │ limit: 3 +│ │ +│ └── • scan +│ missing stats +│ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey +│ spans: [/'us-east-1' - /'us-east-1'] +│ limit: 3 +│ +└── • subquery + │ id: @S1 + │ original sql: (SELECT pk FROM regional_by_row_table_as3 LIMIT 1) + │ exec mode: one row + │ + └── • union all + │ limit: 1 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + │ spans: [/'ap-southeast-2' - /'ap-southeast-2'] + │ limit: 1 + │ + └── • scan + missing stats + table: regional_by_row_table_as3@regional_by_row_table_as3_pkey + spans: [/'us-east-1' - /'us-east-1'] + limit: 1 + +query IIIITT +SELECT (SELECT pk FROM regional_by_row_table_as3 LIMIT 1), b.* FROM regional_by_row_table_as3 b LIMIT 3 +---- +1 1 NULL NULL ca-central-1 ap-southeast-2 +1 2 NULL NULL us-east-1 ap-southeast-2 +1 3 NULL NULL us-east-1 ap-southeast-2 + +# Test partitioning on an index column +statement ok +CREATE TABLE regional_by_row_table_as4 ( + pk int PRIMARY KEY, + a int, + crdb_region_col crdb_internal_region NOT NULL AS ( + CASE + WHEN (a % 3) = 0 THEN 'ap-southeast-2' + WHEN (a % 3) = 1 THEN 'ca-central-1' + ELSE 'us-east-1' + END + ) VIRTUAL, + INDEX a_idx(a), + FAMILY (pk, a) +) LOCALITY REGIONAL BY ROW AS crdb_region_col + +statement ok +INSERT INTO regional_by_row_table_as4 SELECT g, g FROM generate_series(1,1000) g(g) + +# Locality optimized scan with a range query +query T nodeidx=0 +USE multi_region_test_db; +SELECT * FROM [EXPLAIN SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx WHERE a BETWEEN 1 AND 100 LIMIT 10)] OFFSET 2 +---- +· +• group (scalar) +│ +└── • union all + │ limit: 10 + │ + ├── • scan + │ missing stats + │ table: regional_by_row_table_as4@a_idx + │ spans: [/'ap-southeast-2'/1 - /'ap-southeast-2'/100] + │ limit: 10 + │ + └── • scan + missing stats + table: regional_by_row_table_as4@a_idx + spans: [/'ca-central-1'/1 - /'ca-central-1'/100] [/'us-east-1'/1 - /'us-east-1'/100] + limit: 10 + +# Locality optimized scan with a range query +query I nodeidx=0 +USE multi_region_test_db; +SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx WHERE a BETWEEN 1 AND 100 LIMIT 10) +---- +10 + +statement ok +SET vectorize=on + +statement ok nodeidx=0 +USE multi_region_test_db; +SET tracing = on,kv,results; +SELECT count(*) FROM (SELECT * FROM regional_by_row_table_as4@a_idx WHERE a BETWEEN 1 AND 100 LIMIT 10); +SET tracing = off + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/?/3/? -> +fetched: /regional_by_row_table_as4/a_idx/?/6/? -> +fetched: /regional_by_row_table_as4/a_idx/?/9/? -> +fetched: /regional_by_row_table_as4/a_idx/?/12/? -> +fetched: /regional_by_row_table_as4/a_idx/?/15/? -> +fetched: /regional_by_row_table_as4/a_idx/?/18/? -> +fetched: /regional_by_row_table_as4/a_idx/?/21/? -> +fetched: /regional_by_row_table_as4/a_idx/?/24/? -> +fetched: /regional_by_row_table_as4/a_idx/?/27/? -> +fetched: /regional_by_row_table_as4/a_idx/?/30/? -> +output row: [10] + +statement ok +SET vectorize=off + +statement ok +SET tracing = on,kv,results; +SELECT count(*) FROM (SELECT * FROM regional_by_row_table_as4@a_idx WHERE a BETWEEN 1 AND 100 LIMIT 10); +SET tracing = off + +statement ok +RESET vectorize + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/3/3 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/6/6 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/9/9 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/12/12 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/15/15 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/18/18 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/21/21 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/24/24 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/27/27 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/30/30 -> +output row: [10] + +statement ok +SET vectorize=on + +# Locality optimized scan with an IN list +query T +SELECT * FROM [EXPLAIN(OPT) SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a IN (1,2,4,5,6,8,10,11,12,14,15,16,17,18,18,19,22,23,24,25,28,30,33,34,39,40) LIMIT 5)] OFFSET 2 +---- + │ ├── scan regional_by_row_table_as4@a_idx + │ │ ├── constraint: /11/10/9 + │ │ │ ├── [/'ap-southeast-2'/1 - /'ap-southeast-2'/2] + │ │ │ ├── [/'ap-southeast-2'/4 - /'ap-southeast-2'/6] + │ │ │ ├── [/'ap-southeast-2'/8 - /'ap-southeast-2'/8] + │ │ │ ├── [/'ap-southeast-2'/10 - /'ap-southeast-2'/12] + │ │ │ ├── [/'ap-southeast-2'/14 - /'ap-southeast-2'/19] + │ │ │ ├── [/'ap-southeast-2'/22 - /'ap-southeast-2'/25] + │ │ │ ├── [/'ap-southeast-2'/28 - /'ap-southeast-2'/28] + │ │ │ ├── [/'ap-southeast-2'/30 - /'ap-southeast-2'/30] + │ │ │ ├── [/'ap-southeast-2'/33 - /'ap-southeast-2'/34] + │ │ │ └── [/'ap-southeast-2'/39 - /'ap-southeast-2'/40] + │ │ ├── limit: 5 + │ │ └── flags: force-index=a_idx + │ └── scan regional_by_row_table_as4@a_idx + │ ├── constraint: /16/15/14 + │ │ ├── [/'ca-central-1'/1 - /'ca-central-1'/2] + │ │ ├── [/'ca-central-1'/4 - /'ca-central-1'/6] + │ │ ├── [/'ca-central-1'/8 - /'ca-central-1'/8] + │ │ ├── [/'ca-central-1'/10 - /'ca-central-1'/12] + │ │ ├── [/'ca-central-1'/14 - /'ca-central-1'/19] + │ │ ├── [/'ca-central-1'/22 - /'ca-central-1'/25] + │ │ ├── [/'ca-central-1'/28 - /'ca-central-1'/28] + │ │ ├── [/'ca-central-1'/30 - /'ca-central-1'/30] + │ │ ├── [/'ca-central-1'/33 - /'ca-central-1'/34] + │ │ ├── [/'ca-central-1'/39 - /'ca-central-1'/40] + │ │ ├── [/'us-east-1'/1 - /'us-east-1'/2] + │ │ ├── [/'us-east-1'/4 - /'us-east-1'/6] + │ │ ├── [/'us-east-1'/8 - /'us-east-1'/8] + │ │ ├── [/'us-east-1'/10 - /'us-east-1'/12] + │ │ ├── [/'us-east-1'/14 - /'us-east-1'/19] + │ │ ├── [/'us-east-1'/22 - /'us-east-1'/25] + │ │ ├── [/'us-east-1'/28 - /'us-east-1'/28] + │ │ ├── [/'us-east-1'/30 - /'us-east-1'/30] + │ │ ├── [/'us-east-1'/33 - /'us-east-1'/34] + │ │ └── [/'us-east-1'/39 - /'us-east-1'/40] + │ ├── limit: 5 + │ └── flags: force-index=a_idx + └── aggregations + └── count-rows + +statement ok +SET tracing = on,kv,results; +SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a IN (1,2,4,5,6,8,10,11,12,14,15,16,17,18,18,19,22,23,24,25,28,30,33,34,39,40) LIMIT 5); +SET tracing = off + +statement ok +RESET vectorize + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/?/6/? -> +fetched: /regional_by_row_table_as4/a_idx/?/12/? -> +fetched: /regional_by_row_table_as4/a_idx/?/15/? -> +fetched: /regional_by_row_table_as4/a_idx/?/18/? -> +fetched: /regional_by_row_table_as4/a_idx/?/24/? -> +output row: [5] + +statement ok +SET vectorize=off + +statement ok +SET tracing = on,kv,results; +SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a IN (1,2,4,5,6,8,10,11,12,14,15,16,17,18,18,19,22,23,24,25,28,30,33,34,39,40) LIMIT 5); +SET tracing = off + +statement ok +RESET vectorize + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/6/6 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/12/12 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/15/15 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/18/18 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/24/24 -> +output row: [5] + +statement ok +SET vectorize=on + +# Locality optimized scan with multiple range predicates +query T +SELECT * FROM [EXPLAIN(OPT) SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a BETWEEN -1 AND 10 OR a BETWEEN 100 AND 110 OR a BETWEEN 990 AND 1010 LIMIT 9)] OFFSET 2 +---- + │ ├── scan regional_by_row_table_as4@a_idx + │ │ ├── constraint: /11/10/9 + │ │ │ ├── [/'ap-southeast-2'/-1 - /'ap-southeast-2'/10] + │ │ │ ├── [/'ap-southeast-2'/100 - /'ap-southeast-2'/110] + │ │ │ └── [/'ap-southeast-2'/990 - /'ap-southeast-2'/1010] + │ │ ├── limit: 9 + │ │ └── flags: force-index=a_idx + │ └── scan regional_by_row_table_as4@a_idx + │ ├── constraint: /16/15/14 + │ │ ├── [/'ca-central-1'/-1 - /'ca-central-1'/10] + │ │ ├── [/'ca-central-1'/100 - /'ca-central-1'/110] + │ │ ├── [/'ca-central-1'/990 - /'ca-central-1'/1010] + │ │ ├── [/'us-east-1'/-1 - /'us-east-1'/10] + │ │ ├── [/'us-east-1'/100 - /'us-east-1'/110] + │ │ └── [/'us-east-1'/990 - /'us-east-1'/1010] + │ ├── limit: 9 + │ └── flags: force-index=a_idx + └── aggregations + └── count-rows + +statement ok +SET tracing = on,kv,results; +SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a BETWEEN -1 AND 10 OR a BETWEEN 100 AND 110 OR a BETWEEN 990 AND 1010 LIMIT 9); +SET tracing = off + +statement ok +RESET vectorize + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/?/3/? -> +fetched: /regional_by_row_table_as4/a_idx/?/6/? -> +fetched: /regional_by_row_table_as4/a_idx/?/9/? -> +fetched: /regional_by_row_table_as4/a_idx/?/102/? -> +fetched: /regional_by_row_table_as4/a_idx/?/105/? -> +fetched: /regional_by_row_table_as4/a_idx/?/108/? -> +fetched: /regional_by_row_table_as4/a_idx/?/990/? -> +fetched: /regional_by_row_table_as4/a_idx/?/993/? -> +fetched: /regional_by_row_table_as4/a_idx/?/996/? -> +output row: [9] + +statement ok +SET vectorize=off + +statement ok +SET tracing = on,kv,results; +SELECT count(*) FROM +(SELECT * FROM regional_by_row_table_as4@a_idx + WHERE a BETWEEN -1 AND 10 OR a BETWEEN 100 AND 110 OR a BETWEEN 990 AND 1010 LIMIT 9); +SET tracing = off + +statement ok +RESET vectorize + +# If the rows are found in the local region, the other regions are not searched. +query T +SELECT message FROM [SHOW KV TRACE FOR SESSION] WITH ORDINALITY + WHERE message LIKE 'fetched:%' OR message LIKE 'output row%' + ORDER BY ordinality ASC +---- +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/3/3 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/6/6 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/9/9 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/102/102 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/105/105 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/108/108 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/990/990 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/993/993 -> +fetched: /regional_by_row_table_as4/a_idx/'ap-southeast-2'/996/996 -> +output row: [9] + +statement ok +SET vectorize=on diff --git a/pkg/sql/opt/constraint/constraint.go b/pkg/sql/opt/constraint/constraint.go index 02aaa3b18386..d41c7c08c8d9 100644 --- a/pkg/sql/opt/constraint/constraint.go +++ b/pkg/sql/opt/constraint/constraint.go @@ -469,16 +469,68 @@ func (c *Constraint) Combine(evalCtx *tree.EvalContext, other *Constraint) { } } +// onlyOneSpanIsLocal is a helper function for ConsolidateSpans to determine +// whether the end of the last span or the start of the current span are in +// the local region, but not both. +func onlyOneSpanIsLocal( + sp *Span, last *Span, localRegion string, +) (onlyOneSpanIsLocal bool, firstColIsRegionType bool) { + firstColIsRegionType = true + var spanStartRegion string + var lastSpanEndRegion string + var spanStartRegionIsLocal, lastSpanEndRegionIsLocal bool + var ok bool + if spanStartRegion, ok = sp.start.GetInternalRegionNameFromPrefix(); !ok { + firstColIsRegionType = false + } + spanStartRegionIsLocal = spanStartRegion == localRegion + if lastSpanEndRegion, ok = last.end.GetInternalRegionNameFromPrefix(); !ok { + firstColIsRegionType = false + } + lastSpanEndRegionIsLocal = lastSpanEndRegion == localRegion + if spanStartRegionIsLocal || lastSpanEndRegionIsLocal { + onlyOneSpanIsLocal = spanStartRegionIsLocal != lastSpanEndRegionIsLocal + } else { + onlyOneSpanIsLocal = false + } + return onlyOneSpanIsLocal, firstColIsRegionType +} + // ConsolidateSpans merges spans that have consecutive boundaries. For example: // [/1 - /2] [/3 - /4] becomes [/1 - /4]. func (c *Constraint) ConsolidateSpans(evalCtx *tree.EvalContext) { keyCtx := KeyContext{Columns: c.Columns, EvalCtx: evalCtx} var result Spans + + if c.Spans.Count() < 1 { + return + } + firstColIsRegionType := c.Spans.Get(0).StartKey().PrefixIsInternalRegionType() + var localRegion string + if firstColIsRegionType { + // Reset firstColIsRegionType to false if we failed to find the local region + // name, for whatever reason. This prevents the comparison of the span + // prefix region names in the code below to an uninitialized region name. + localRegion, firstColIsRegionType = evalCtx.Locality.Find("region") + } + + var localRemoteCrossover bool for i := 1; i < c.Spans.Count(); i++ { last := c.Spans.Get(i - 1) sp := c.Spans.Get(i) + if firstColIsRegionType { + // Detect when there is a crossover between the last span and current span + // from a local region to remote, or remote to local. + localRemoteCrossover, firstColIsRegionType = onlyOneSpanIsLocal(sp, last, localRegion) + } + // Do not merge local spans with remote spans because a span must be 100% + // local in order to utilize locality optimized search. + // An example query on a LOCALITY REGIONAL BY ROW table which this + // benefits is: + // SELECT * FROM regional_by_row_table WHERE pk <> 4 LIMIT 3; if last.endBoundary == IncludeBoundary && sp.startBoundary == IncludeBoundary && - sp.start.IsNextKey(&keyCtx, last.end) { + sp.start.IsNextKey(&keyCtx, last.end) && + (!firstColIsRegionType || !localRemoteCrossover) { // We only initialize `result` if we need to change something. if result.Count() == 0 { result.Alloc(c.Spans.Count() - 1) diff --git a/pkg/sql/opt/constraint/key.go b/pkg/sql/opt/constraint/key.go index fac3f0304a06..0723be82c5d7 100644 --- a/pkg/sql/opt/constraint/key.go +++ b/pkg/sql/opt/constraint/key.go @@ -15,6 +15,7 @@ import ( "fmt" "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" + "github.com/cockroachdb/cockroach/pkg/sql/types" ) // EmptyKey has zero values. If it's a start key, then it sorts before all @@ -276,6 +277,37 @@ func (k Key) Prev(keyCtx *KeyContext) (_ Key, ok bool) { return Key{firstVal: k.firstVal, otherVals: vals}, true } +// GetInternalRegionNameFromPrefix returns the region name contained in the +// firstVal of Key k, if firstVal is of type crdb_internal region. Otherwise, +// it returns a zero-length string. The second return value indicates success. +func (k Key) GetInternalRegionNameFromPrefix() (string, bool) { + firstKeyColumn := k.firstVal + if firstKeyColumn != nil { + firstKeyColumnType := firstKeyColumn.ResolvedType() + if types.IsCRDBInternalRegionType(firstKeyColumnType) { + var enum *tree.DEnum + var ok bool + if enum, ok = firstKeyColumn.(*tree.DEnum); !ok { + return "", false + } + return enum.LogicalRep, true + } + } + return "", false +} + +// PrefixIsInternalRegionType returns true if Key k's firstVal is of type +// crdb_internal_region. +func (k Key) PrefixIsInternalRegionType() bool { + var firstKeyColumnType *types.T + firstKeyColumn := k.firstVal + if firstKeyColumn != nil { + firstKeyColumnType = firstKeyColumn.ResolvedType() + return types.IsCRDBInternalRegionType(firstKeyColumnType) + } + return false +} + // String formats a key like this: // EmptyKey : empty string // Key with 1 value : /2 diff --git a/pkg/sql/opt/table_meta.go b/pkg/sql/opt/table_meta.go index d4cf12bd882c..2274e1e2c0b0 100644 --- a/pkg/sql/opt/table_meta.go +++ b/pkg/sql/opt/table_meta.go @@ -325,6 +325,12 @@ func (tm *TableMeta) VirtualComputedColumns() ColSet { return virtualCols } +// FirstColumnIDOfIndex returns the ColumnID of the index with ordinal number +// "index" of the table described by tabMeta. +func (tm *TableMeta) FirstColumnIDOfIndex(index cat.IndexOrdinal) ColumnID { + return tm.MetaID.ColumnID(tm.Table.Index(index).Column(0).Ordinal()) +} + // TableAnnotation returns the given annotation that is associated with the // given table. If the table has no such annotation, TableAnnotation returns // nil. diff --git a/pkg/sql/opt/xform/scan_funcs.go b/pkg/sql/opt/xform/scan_funcs.go index ab870c075d17..f211a9358387 100644 --- a/pkg/sql/opt/xform/scan_funcs.go +++ b/pkg/sql/opt/xform/scan_funcs.go @@ -16,6 +16,7 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/opt/constraint" "github.com/cockroachdb/cockroach/pkg/sql/opt/memo" "github.com/cockroachdb/cockroach/pkg/sql/rowinfra" + "github.com/cockroachdb/cockroach/pkg/sql/types" "github.com/cockroachdb/cockroach/pkg/util" "github.com/cockroachdb/errors" ) @@ -110,21 +111,25 @@ func (c *CustomFuncs) CanMaybeGenerateLocalityOptimizedScan(scanPrivate *memo.Sc return false } - if scanPrivate.HardLimit != 0 { - // This optimization doesn't apply to limited scans. - return false - } - - // This scan should have at least two spans, or we won't be able to move one - // of the spans to a separate remote scan. - if scanPrivate.Constraint == nil || scanPrivate.Constraint.Spans.Count() < 2 { - return false - } + if scanPrivate.Constraint == nil { + // If not a limited scan, then we must have a constraint to analyze spans. + // If a limited scan, then use the heuristic that anything larger than a + // single KV batch should not use this optimization. + if scanPrivate.HardLimit == 0 || rowinfra.KeyLimit(scanPrivate.HardLimit) > rowinfra.ProductionKVBatchSize { + return false + } + } else { + // This scan should have at least two spans, or we won't be able to move one + // of the spans to a separate remote scan. + if scanPrivate.Constraint.Spans.Count() < 2 { + return false + } - // Don't apply the rule if there are too many spans, since the rule code is - // O(# spans * # prefixes * # datums per prefix). - if scanPrivate.Constraint.Spans.Count() > 10000 { - return false + // Don't apply the rule if there are too many spans, since the rule code is + // O(# spans * # prefixes * # datums per prefix). + if scanPrivate.Constraint.Spans.Count() > 10000 { + return false + } } // There should be at least two partitions, or we won't be able to @@ -154,7 +159,12 @@ func (c *CustomFuncs) GenerateLocalityOptimizedScan( // we're scanning multiple batches. // TODO(rytaft): Revisit this when we have a more accurate cost model for data // distribution. - if rowinfra.KeyLimit(grp.Relational().Cardinality.Max) > rowinfra.ProductionKVBatchSize { + maxRows := rowinfra.KeyLimit(grp.Relational().Cardinality.Max) + hardLimit := rowinfra.KeyLimit(scanPrivate.HardLimit) + if hardLimit > 0 && hardLimit < maxRows { + maxRows = hardLimit + } + if maxRows > rowinfra.ProductionKVBatchSize { return } @@ -179,20 +189,35 @@ func (c *CustomFuncs) GenerateLocalityOptimizedScan( return } - localSpans := c.getLocalSpans(index, localPartitions, scanPrivate.Constraint) - if localSpans.Len() == 0 || localSpans.Len() == scanPrivate.Constraint.Spans.Count() { + // If the Scan has no Constraint, lookup and use the implicit check constraint + // 'crdb_region IN (, ... )' stored in the + // table metadata. That includes all regions in the database, so is equivalent + // to a nil Constraint. + var constraint *constraint.Constraint + var ok bool + if scanPrivate.Constraint == nil { + if constraint, ok = c.getCrdbRegionCheckConstraint(scanPrivate); !ok { + return + } + } else { + constraint = scanPrivate.Constraint + } + + localSpans := c.getLocalSpans(index, localPartitions, constraint) + if localSpans.Len() == 0 || localSpans.Len() == constraint.Spans.Count() { // The spans target all local or all remote partitions. return } // Split the spans into local and remote sets. - localConstraint, remoteConstraint := c.splitSpans(scanPrivate.Constraint, localSpans) + localConstraint, remoteConstraint := c.splitSpans(constraint, localSpans) // Create the local scan. localScanPrivate := c.DuplicateScanPrivate(scanPrivate) localScanPrivate.LocalityOptimized = true localConstraint.Columns = localConstraint.Columns.RemapColumns(scanPrivate.Table, localScanPrivate.Table) localScanPrivate.SetConstraint(c.e.evalCtx, &localConstraint) + localScanPrivate.HardLimit = scanPrivate.HardLimit localScan := c.e.f.ConstructScan(localScanPrivate) // Create the remote scan. @@ -200,6 +225,7 @@ func (c *CustomFuncs) GenerateLocalityOptimizedScan( remoteScanPrivate.LocalityOptimized = true remoteConstraint.Columns = remoteConstraint.Columns.RemapColumns(scanPrivate.Table, remoteScanPrivate.Table) remoteScanPrivate.SetConstraint(c.e.evalCtx, &remoteConstraint) + remoteScanPrivate.HardLimit = scanPrivate.HardLimit remoteScan := c.e.f.ConstructScan(remoteScanPrivate) // Add the LocalityOptimizedSearchExpr to the same group as the original scan. @@ -215,6 +241,53 @@ func (c *CustomFuncs) GenerateLocalityOptimizedScan( c.e.mem.AddLocalityOptimizedSearchToGroup(&locOptSearch, grp) } +// getCrdbRegionCheckConstraint examines the Constraints in the metadata of the +// table specified by scanPrivate and returns the Constraint which references +// crdb_internal_region, if such a Constraint exists. +func (c *CustomFuncs) getCrdbRegionCheckConstraint( + scanPrivate *memo.ScanPrivate, +) (*constraint.Constraint, bool) { + tabMeta := c.e.mem.Metadata().TableMeta(scanPrivate.Table) + var checkConstraints *memo.FiltersExpr + var ok bool + if checkConstraints, ok = tabMeta.Constraints.(*memo.FiltersExpr); !ok { + return nil, false + } + firstColOfIndex := tabMeta.FirstColumnIDOfIndex(scanPrivate.Index) + + for chkIdx := 0; chkIdx < len(*checkConstraints); chkIdx++ { + checkConstraint := (*checkConstraints)[chkIdx] + + firstSpan := checkConstraint.ScalarProps().Constraints.Constraint(0).Spans.Get(0) + if firstSpan.IsUnconstrained() { + continue + } + // If there are any user-defined check constraints on a column of type + // crdb_internal_region, they may take any form. The system-generated check + // constraint is always an IN expression, so let's only look at those. + if checkConstraint.Condition.Op() != opt.InOp { + continue + } + if checkConstraint.Condition.Child(0).Op() != opt.VariableOp { + continue + } + variableExpr := checkConstraint.Condition.Child(0).(*memo.VariableExpr) + // There may be a user-defined IN predicate check constraint on another + // crdb_internal_region column. The one we care about is always the first + // column of the index. + if variableExpr.Col != firstColOfIndex { + continue + } + keyType := firstSpan.StartKey().Value(0).ResolvedType() + // The last step is to verify the key column is of type + // crdb_internal_region. If it is, we've found the crdb_region constraint. + if types.IsCRDBInternalRegionType(keyType) { + return checkConstraint.ScalarProps().Constraints.Constraint(0), true + } + } + return nil, false +} + // getLocalSpans returns the indexes of the spans from the given constraint that // target local partitions. func (c *CustomFuncs) getLocalSpans( diff --git a/pkg/sql/opt/xform/testdata/rules/scan b/pkg/sql/opt/xform/testdata/rules/scan index a3efc61852be..783785810773 100644 --- a/pkg/sql/opt/xform/testdata/rules/scan +++ b/pkg/sql/opt/xform/testdata/rules/scan @@ -822,30 +822,37 @@ distribute └── fd: ()-->(1,3,4) # The scan is limited. -opt locality=(region=east) expect-not=GenerateLocalityOptimizedScan +opt locality=(region=east) expect=GenerateLocalityOptimizedScan SELECT a FROM abc_part WHERE d = 1 LIMIT 1 ---- -distribute +project ├── columns: a:3!null ├── cardinality: [0 - 1] ├── key: () ├── fd: ()-->(3) ├── distribution: east - ├── input distribution: central,east,west - └── project - ├── columns: a:3!null + └── locality-optimized-search + ├── columns: a:3!null d:6!null + ├── left columns: a:11 d:14 + ├── right columns: a:19 d:22 ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(3) + ├── fd: ()-->(3,6) + ├── distribution: east + ├── scan abc_part@d_idx + │ ├── columns: a:11!null d:14!null + │ ├── constraint: /9/14/11: [/'east'/1 - /'east'/1] + │ ├── limit: 1 + │ ├── key: () + │ └── fd: ()-->(11,14) └── scan abc_part@d_idx - ├── columns: a:3!null d:6!null - ├── constraint: /1/6/3 + ├── columns: a:19!null d:22!null + ├── constraint: /17/22/19 │ ├── [/'central'/1 - /'central'/1] - │ ├── [/'east'/1 - /'east'/1] │ └── [/'west'/1 - /'west'/1] ├── limit: 1 ├── key: () - └── fd: ()-->(3,6) + └── fd: ()-->(19,22) # The scan is limited, but b is known to be a key, so the limit is discarded. opt locality=(region=east) expect=GenerateLocalityOptimizedScan diff --git a/pkg/sql/types/types.go b/pkg/sql/types/types.go index eec896d3a285..e8a06dacadb9 100644 --- a/pkg/sql/types/types.go +++ b/pkg/sql/types/types.go @@ -2739,6 +2739,15 @@ func IsSerialType(typ *T) bool { return typ == &Serial2Type || typ == &Serial4Type || typ == &Serial8Type } +// IsCRDBInternalRegionType returns whether or not the input type is of type +// crdb_internal_region. +func IsCRDBInternalRegionType(typ *T) bool { + if typ == nil { + return false + } + return typ.UserDefined() && typ.TypeMeta.Name.Name == "crdb_internal_region" +} + // unreservedTypeTokens contain type alias that we resolve during parsing. // Instead of adding a new token to the parser, add the type here. var unreservedTypeTokens = map[string]*T{