From 48274d63dee0adf06400a25fff233de4ae4d1eb7 Mon Sep 17 00:00:00 2001 From: Rebecca Taft Date: Mon, 16 Dec 2024 18:00:14 -0600 Subject: [PATCH] opt,sql: support hint to avoid full scan 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};. 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. --- pkg/sql/logictest/testdata/logic_test/select | 19 ++++ pkg/sql/opt/exec/execbuilder/testdata/delete | 30 +++++ .../exec/execbuilder/testdata/explain_redact | 4 +- pkg/sql/opt/exec/execbuilder/testdata/update | 35 ++++++ pkg/sql/opt/exec/execbuilder/testdata/upsert | 106 ++++++++++++++++++ pkg/sql/opt/memo/expr.go | 3 + pkg/sql/opt/memo/expr_format.go | 3 + pkg/sql/opt/memo/interner.go | 1 + pkg/sql/opt/memo/interner_test.go | 4 +- pkg/sql/opt/optbuilder/select.go | 1 + pkg/sql/opt/xform/coster.go | 27 +++-- pkg/sql/opt/xform/testdata/coster/scan | 53 ++++++++- pkg/sql/opt/xform/testdata/rules/groupby | 4 +- pkg/sql/opt/xform/testdata/rules/join | 8 +- pkg/sql/opt/xform/testdata/rules/select | 2 +- pkg/sql/opt/xform/testdata/rules/set | 2 +- pkg/sql/parser/sql.y | 9 +- pkg/sql/parser/testdata/hints | 8 ++ pkg/sql/sem/tree/select.go | 18 ++- 19 files changed, 313 insertions(+), 24 deletions(-) diff --git a/pkg/sql/logictest/testdata/logic_test/select b/pkg/sql/logictest/testdata/logic_test/select index a4a3920132fa..de6880168c72 100644 --- a/pkg/sql/logictest/testdata/logic_test/select +++ b/pkg/sql/logictest/testdata/logic_test/select @@ -756,6 +756,25 @@ SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_idx,NO_FULL_SCAN} WHERE b > 0 statement ok SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_partial,NO_FULL_SCAN} WHERE a > 0 AND b = 1 +# Now avoid full scans with a hint. A full scan should not cause an error. +statement ok +SELECT * FROM t_disallow_scans@{AVOID_FULL_SCAN} + +statement ok +SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_idx,AVOID_FULL_SCAN} + +statement ok +SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_partial,AVOID_FULL_SCAN} WHERE a > 0 + +statement ok +SELECT * FROM t_disallow_scans@{AVOID_FULL_SCAN} WHERE a > 0 + +statement ok +SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_idx,AVOID_FULL_SCAN} WHERE b > 0 + +statement ok +SELECT * FROM t_disallow_scans@{FORCE_INDEX=b_partial,AVOID_FULL_SCAN} WHERE a > 0 AND b = 1 + # Now disable full scans with the session variable. statement ok SET disallow_full_table_scans = true; diff --git a/pkg/sql/opt/exec/execbuilder/testdata/delete b/pkg/sql/opt/exec/execbuilder/testdata/delete index c2c6f253dce3..cb04752d2a05 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/delete +++ b/pkg/sql/opt/exec/execbuilder/testdata/delete @@ -345,6 +345,36 @@ vectorized: true spans: /1-/1000 /2001-/3000 locking strength: for update +# AVOID_FULL_SCAN also works to ensure a constrained scan. +query T +EXPLAIN (VERBOSE) DELETE FROM xyz@{AVOID_FULL_SCAN} WHERE (y > 0 AND y < 1000) OR (y > 2000 AND y < 3000) RETURNING z +---- +distribution: local +vectorized: true +· +• project +│ columns: (z) +│ +└── • delete + │ columns: (x, z) + │ estimated row count: 990 (missing stats) + │ from: xyz + │ auto commit + │ + └── • index join + │ columns: (x, y, z) + │ estimated row count: 990 (missing stats) + │ table: xyz@xyz_pkey + │ key columns: x + │ locking strength: for update + │ + └── • scan + columns: (x, y) + estimated row count: 990 (missing stats) + table: xyz@xyz_y_idx + spans: /1-/1000 /2001-/3000 + locking strength: for update + # Testcase for issue 105803. statement ok diff --git a/pkg/sql/opt/exec/execbuilder/testdata/explain_redact b/pkg/sql/opt/exec/execbuilder/testdata/explain_redact index 8291ed8aa126..ff0b5ccd6dc4 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/explain_redact +++ b/pkg/sql/opt/exec/execbuilder/testdata/explain_redact @@ -1156,7 +1156,7 @@ update ab query T EXPLAIN (OPT, MEMO, REDACT) UPDATE ab SET a = a || 'ab' WHERE a > 'a' ---- -memo (optimized, ~13KB, required=[presentation: info:15] [distribution: test]) +memo (optimized, ~14KB, required=[presentation: info:15] [distribution: test]) ├── G1: (explain G2 [distribution: test]) │ └── [presentation: info:15] [distribution: test] │ ├── best: (explain G2="[distribution: test]" [distribution: test]) @@ -3825,7 +3825,7 @@ project query T EXPLAIN (OPT, MEMO, REDACT) SELECT min(c || 'cccc') OVER (ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING EXCLUDE CURRENT ROW) FROM cd ---- -memo (optimized, ~11KB, required=[presentation: info:10] [distribution: test]) +memo (optimized, ~12KB, required=[presentation: info:10] [distribution: test]) ├── G1: (explain G2 [presentation: min:8] [distribution: test]) │ └── [presentation: info:10] [distribution: test] │ ├── best: (explain G2="[presentation: min:8] [distribution: test]" [presentation: min:8] [distribution: test]) diff --git a/pkg/sql/opt/exec/execbuilder/testdata/update b/pkg/sql/opt/exec/execbuilder/testdata/update index c8c8ed5ec832..fc9751116f14 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/update +++ b/pkg/sql/opt/exec/execbuilder/testdata/update @@ -268,6 +268,41 @@ vectorized: true spans: /1-/1000 /2001-/3000 locking strength: for update +# AVOID_FULL_SCAN also works to ensure a constrained scan. +query T +EXPLAIN (VERBOSE) UPDATE xyz@{AVOID_FULL_SCAN} SET x = 5 WHERE (y > 0 AND y < 1000) OR (y > 2000 AND y < 3000) +---- +distribution: local +vectorized: true +· +• update +│ columns: () +│ estimated row count: 0 (missing stats) +│ table: xyz +│ set: x +│ auto commit +│ +└── • render + │ columns: (x, y, z, x_new) + │ render x_new: 5 + │ render x: x + │ render y: y + │ render z: z + │ + └── • index join + │ columns: (x, y, z) + │ estimated row count: 990 (missing stats) + │ table: xyz@xyz_pkey + │ key columns: x + │ locking strength: for update + │ + └── • scan + columns: (x, y) + estimated row count: 990 (missing stats) + table: xyz@y_idx + spans: /1-/1000 /2001-/3000 + locking strength: for update + statement ok CREATE TABLE pks ( k1 INT, diff --git a/pkg/sql/opt/exec/execbuilder/testdata/upsert b/pkg/sql/opt/exec/execbuilder/testdata/upsert index 8248ac7aecab..f29521f2618f 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/upsert +++ b/pkg/sql/opt/exec/execbuilder/testdata/upsert @@ -410,6 +410,112 @@ vectorized: true query error could not produce a query plan conforming to the NO_FULL_SCAN hint EXPLAIN (VERBOSE) UPSERT INTO indexed@{FORCE_INDEX=secondary,NO_FULL_SCAN} VALUES (1) +# AVOID_FULL_SCAN also works to ensure a constrained scan, and does not error if +# one is not possible. +query T +EXPLAIN (VERBOSE) UPSERT INTO indexed@{AVOID_FULL_SCAN} VALUES (1) +---- +distribution: local +vectorized: true +· +• upsert +│ columns: () +│ estimated row count: 0 (missing stats) +│ into: indexed(a, b, c, d) +│ auto commit +│ arbiter indexes: indexed_pkey +│ +└── • project + │ columns: (column1, b_default, c_default, d_comp, a, b, c, d, b_default, c_default, d_comp, a, check1) + │ + └── • render + │ columns: (check1, column1, b_default, c_default, d_comp, a, b, c, d) + │ render check1: c_default > 0 + │ render column1: column1 + │ render b_default: b_default + │ render c_default: c_default + │ render d_comp: d_comp + │ render a: a + │ render b: b + │ render c: c + │ render d: d + │ + └── • cross join (left outer) + │ columns: (column1, b_default, c_default, d_comp, a, b, c, d) + │ estimated row count: 1 (missing stats) + │ + ├── • values + │ columns: (column1, b_default, c_default, d_comp) + │ size: 4 columns, 1 row + │ row 0, expr 0: 1 + │ row 0, expr 1: CAST(NULL AS INT8) + │ row 0, expr 2: 10 + │ row 0, expr 3: 11 + │ + └── • scan + columns: (a, b, c, d) + estimated row count: 1 (missing stats) + table: indexed@indexed_pkey + spans: /1/0 + locking strength: for update + +query T +EXPLAIN (VERBOSE) UPSERT INTO indexed@{FORCE_INDEX=secondary,AVOID_FULL_SCAN} VALUES (1) +---- +distribution: local +vectorized: true +· +• upsert +│ columns: () +│ estimated row count: 0 (missing stats) +│ into: indexed(a, b, c, d) +│ auto commit +│ arbiter indexes: indexed_pkey +│ +└── • project + │ columns: (column1, b_default, c_default, d_comp, a, b, c, d, b_default, c_default, d_comp, a, check1) + │ + └── • render + │ columns: (check1, column1, b_default, c_default, d_comp, a, b, c, d) + │ render check1: c_default > 0 + │ render column1: column1 + │ render b_default: b_default + │ render c_default: c_default + │ render d_comp: d_comp + │ render a: a + │ render b: b + │ render c: c + │ render d: d + │ + └── • cross join (left outer) + │ columns: (column1, b_default, c_default, d_comp, a, b, c, d) + │ estimated row count: 1 (missing stats) + │ + ├── • values + │ columns: (column1, b_default, c_default, d_comp) + │ size: 4 columns, 1 row + │ row 0, expr 0: 1 + │ row 0, expr 1: CAST(NULL AS INT8) + │ row 0, expr 2: 10 + │ row 0, expr 3: 11 + │ + └── • filter + │ columns: (a, b, c, d) + │ estimated row count: 1 (missing stats) + │ filter: a = 1 + │ + └── • index join + │ columns: (a, b, c, d) + │ estimated row count: 1,000 (missing stats) + │ table: indexed@indexed_pkey + │ key columns: a + │ + └── • scan + columns: (a, b, d) + estimated row count: 1,000 (missing stats) + table: indexed@secondary + spans: FULL SCAN + query T EXPLAIN (VERBOSE) INSERT INTO indexed@indexed_pkey AS indexed_pk diff --git a/pkg/sql/opt/memo/expr.go b/pkg/sql/opt/memo/expr.go index aea37e43199c..6c10ed2bae16 100644 --- a/pkg/sql/opt/memo/expr.go +++ b/pkg/sql/opt/memo/expr.go @@ -409,6 +409,9 @@ type ScanFlags struct { // NoFullScan disallows use of a full scan for scanning this table. NoFullScan bool + // AvoidFullScan avoids use of a full scan for scanning this table. + AvoidFullScan bool + // ForceIndex forces the use of a specific index (specified in Index). // ForceIndex and NoIndexJoin cannot both be set at the same time. ForceIndex bool diff --git a/pkg/sql/opt/memo/expr_format.go b/pkg/sql/opt/memo/expr_format.go index b39c3b669179..0df2658ef591 100644 --- a/pkg/sql/opt/memo/expr_format.go +++ b/pkg/sql/opt/memo/expr_format.go @@ -514,6 +514,9 @@ func (f *ExprFmtCtx) formatRelational(e RelExpr, tp treeprinter.Node) { if private.Flags.NoFullScan { b.WriteString(" no-full-scan") } + if private.Flags.AvoidFullScan { + b.WriteString(" avoid-full-scan") + } if private.Flags.ForceZigzag { if private.Flags.ZigzagIndexes.Empty() { b.WriteString(" force-zigzag") diff --git a/pkg/sql/opt/memo/interner.go b/pkg/sql/opt/memo/interner.go index 6940755df138..f65d7114ff2d 100644 --- a/pkg/sql/opt/memo/interner.go +++ b/pkg/sql/opt/memo/interner.go @@ -509,6 +509,7 @@ func (h *hasher) HashScanFlags(val ScanFlags) { h.HashBool(val.NoIndexJoin) h.HashBool(val.NoZigzagJoin) h.HashBool(val.NoFullScan) + h.HashBool(val.AvoidFullScan) h.HashBool(val.ForceIndex) h.HashBool(val.ForceInvertedIndex) h.HashBool(val.ForceZigzag) diff --git a/pkg/sql/opt/memo/interner_test.go b/pkg/sql/opt/memo/interner_test.go index ee2b8651ebe7..b5c0e39e8b5d 100644 --- a/pkg/sql/opt/memo/interner_test.go +++ b/pkg/sql/opt/memo/interner_test.go @@ -402,7 +402,7 @@ func TestInterner(t *testing.T) { {hashFn: in.hasher.HashScanFlags, eqFn: in.hasher.IsScanFlagsEqual, variations: []testVariation{ // Use unnamed fields so that compilation fails if a new field is // added to ScanFlags. - {val1: ScanFlags{false, false, false, false, false, false, false, 0, 0, intsets.Fast{}}, val2: ScanFlags{}, equal: true}, + {val1: ScanFlags{false, false, false, false, false, false, false, false, 0, 0, intsets.Fast{}}, val2: ScanFlags{}, equal: true}, {val1: ScanFlags{}, val2: ScanFlags{}, equal: true}, {val1: ScanFlags{NoIndexJoin: false}, val2: ScanFlags{NoIndexJoin: true}, equal: false}, {val1: ScanFlags{NoIndexJoin: true}, val2: ScanFlags{NoIndexJoin: true}, equal: true}, @@ -417,6 +417,8 @@ func TestInterner(t *testing.T) { {val1: ScanFlags{NoIndexJoin: true, Index: 1}, val2: ScanFlags{NoIndexJoin: false, Index: 1}, equal: false}, {val1: ScanFlags{NoFullScan: true}, val2: ScanFlags{NoFullScan: false}, equal: false}, {val1: ScanFlags{NoFullScan: true}, val2: ScanFlags{NoFullScan: true}, equal: true}, + {val1: ScanFlags{AvoidFullScan: true}, val2: ScanFlags{AvoidFullScan: false}, equal: false}, + {val1: ScanFlags{AvoidFullScan: true}, val2: ScanFlags{AvoidFullScan: true}, equal: true}, {val1: ScanFlags{ForceInvertedIndex: true}, val2: ScanFlags{ForceInvertedIndex: false}, equal: false}, {val1: ScanFlags{ForceInvertedIndex: true}, val2: ScanFlags{ForceInvertedIndex: true}, equal: true}, { diff --git a/pkg/sql/opt/optbuilder/select.go b/pkg/sql/opt/optbuilder/select.go index fcea9dbab467..0c2e74fe0deb 100644 --- a/pkg/sql/opt/optbuilder/select.go +++ b/pkg/sql/opt/optbuilder/select.go @@ -648,6 +648,7 @@ func (b *Builder) buildScan( private.Flags.NoIndexJoin = indexFlags.NoIndexJoin private.Flags.NoZigzagJoin = indexFlags.NoZigzagJoin private.Flags.NoFullScan = indexFlags.NoFullScan + private.Flags.AvoidFullScan = indexFlags.AvoidFullScan private.Flags.ForceInvertedIndex = indexFlags.ForceInvertedIndex if indexFlags.Index != "" || indexFlags.IndexID != 0 { idx := -1 diff --git a/pkg/sql/opt/xform/coster.go b/pkg/sql/opt/xform/coster.go index ff7609c89ae2..d44fd7acbc98 100644 --- a/pkg/sql/opt/xform/coster.go +++ b/pkg/sql/opt/xform/coster.go @@ -151,6 +151,12 @@ const ( // plan that could satisfy the hints. hugeCost memo.Cost = 1e100 + // avoidFullScanCostPenalty is the cost to use for full scans when we want to + // avoid them at all costs, but not error in case no other plan is possible. + // We can't use hugeCost directly since it might interfere with other hints + // like forcing a particular index. + avoidFullScanCostPenalty = hugeCost / 10 + // fullScanRowCountPenalty adds a penalty to full table scans. This is especially // useful for empty or very small tables, where we would get plans that are // surprising to users (like full scans instead of point lookups). @@ -758,14 +764,14 @@ func (c *coster) computeScanCost(scan *memo.ScanExpr, required *physical.Require } isUnfiltered := scan.IsUnfiltered(c.mem.Metadata()) - if scan.Flags.NoFullScan { - // Normally a full scan of a partial index would be allowed with the - // NO_FULL_SCAN hint (isUnfiltered is false for partial indexes), but if the - // user has explicitly forced the partial index *and* used NO_FULL_SCAN, we - // disallow the full index scan. - if isUnfiltered || (scan.Flags.ForceIndex && scan.IsFullIndexScan()) { - return hugeCost - } + + // 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 + // (isUnfiltered is false for partial indexes), but if the user has explicitly + // forced the partial index, we do consider it a full scan. + isFullScan := isUnfiltered || (scan.Flags.ForceIndex && scan.IsFullIndexScan()) + if scan.Flags.NoFullScan && isFullScan { + return hugeCost } if scan.Flags.ForceInvertedIndex && !scan.IsInvertedScan(c.mem.Metadata()) { @@ -803,6 +809,11 @@ func (c *coster) computeScanCost(scan *memo.ScanExpr, required *physical.Require } baseCost := memo.Cost(numSpans * randIOCostFactor) + // Add a penalty for a full scan if needed. + if scan.Flags.AvoidFullScan && isFullScan { + baseCost += avoidFullScanCostPenalty + } + // If this is a virtual scan, add the cost of fetching table descriptors. if c.mem.Metadata().Table(scan.Table).IsVirtualTable() { baseCost += virtualScanTableDescriptorFetchCost diff --git a/pkg/sql/opt/xform/testdata/coster/scan b/pkg/sql/opt/xform/testdata/coster/scan index c6ba6ec2eeda..4b721e5cb5ac 100644 --- a/pkg/sql/opt/xform/testdata/coster/scan +++ b/pkg/sql/opt/xform/testdata/coster/scan @@ -585,7 +585,8 @@ scan t@abc ├── key: (1) └── fd: ()-->(2,3), (1)-->(4) -# Test that the NO_FULL_SCAN hint creates a huge cost for full scans. +# Test that the NO_FULL_SCAN and AVOID_FULL_SCAN hints create a huge cost for +# full scans. opt SELECT * FROM t@{NO_FULL_SCAN} ---- @@ -597,6 +598,17 @@ scan t ├── key: (1) └── fd: (1)-->(2-4) +opt +SELECT * FROM t@{AVOID_FULL_SCAN} +---- +scan t + ├── columns: k:1!null a:2 b:3 c:4 + ├── flags: avoid-full-scan + ├── stats: [rows=100000] + ├── cost: 1e+100 + ├── key: (1) + └── fd: (1)-->(2-4) + exec-ddl CREATE INDEX b_partial ON t(b) WHERE c > 0 ---- @@ -619,6 +631,23 @@ index-join t ├── key: (1) └── fd: (1)-->(3) +opt +SELECT * FROM t@{AVOID_FULL_SCAN} WHERE c > 0 +---- +index-join t + ├── columns: k:1!null a:2 b:3 c:4!null + ├── stats: [rows=33003.3, distinct(4)=3333.33, null(4)=0] + ├── cost: 234671.505 + ├── key: (1) + ├── fd: (1)-->(2-4) + └── scan t@b_partial,partial + ├── columns: k:1!null b:3 + ├── flags: avoid-full-scan + ├── stats: [rows=33003.3, distinct(4)=3333.33, null(4)=0] + ├── cost: 34341.4524 + ├── key: (1) + └── fd: (1)-->(3) + opt SELECT * FROM t@{FORCE_INDEX=b_partial,NO_FULL_SCAN} WHERE c > 0 ---- @@ -641,6 +670,28 @@ select └── filters └── c:4 > 0 [outer=(4), constraints=(/4: [/1 - ]; tight)] +opt +SELECT * FROM t@{FORCE_INDEX=b_partial,AVOID_FULL_SCAN} WHERE c > 0 +---- +select + ├── columns: k:1!null a:2 b:3 c:4!null + ├── stats: [rows=33003.3, distinct(4)=3333.33, null(4)=0] + ├── cost: 1e+100 + ├── key: (1) + ├── fd: (1)-->(2-4) + ├── scan t + │ ├── columns: k:1!null a:2 b:3 c:4 + │ ├── partial index predicates + │ │ └── b_partial: filters + │ │ └── c:4 > 0 [outer=(4), constraints=(/4: [/1 - ]; tight)] + │ ├── flags: force-index=b_partial avoid-full-scan + │ ├── stats: [rows=100000, distinct(1)=3, null(1)=0, distinct(4)=10000, null(4)=1000] + │ ├── cost: 1e+100 + │ ├── key: (1) + │ └── fd: (1)-->(2-4) + └── filters + └── c:4 > 0 [outer=(4), constraints=(/4: [/1 - ]; tight)] + # Test that the FORCE_INVERTED_INDEX hint creates a huge cost for full table # scans. opt diff --git a/pkg/sql/opt/xform/testdata/rules/groupby b/pkg/sql/opt/xform/testdata/rules/groupby index adb4f9098953..5a8ce3f0d1e0 100644 --- a/pkg/sql/opt/xform/testdata/rules/groupby +++ b/pkg/sql/opt/xform/testdata/rules/groupby @@ -1892,7 +1892,7 @@ memo (optimized, ~15KB, required=[presentation: array_agg:7]) memo SELECT sum(k) FROM (SELECT * FROM kuvw WHERE u=v) GROUP BY u,w ---- -memo (optimized, ~15KB, required=[presentation: sum:7]) +memo (optimized, ~16KB, required=[presentation: sum:7]) ├── G1: (project G2 G3 sum) │ └── [presentation: sum:7] │ ├── best: (project G2 G3 sum) @@ -1995,7 +1995,7 @@ memo (optimized, ~9KB, required=[presentation: array_agg:7]) memo SELECT DISTINCT u, v, w FROM kuvw ---- -memo (optimized, ~6KB, required=[presentation: u:2,v:3,w:4]) +memo (optimized, ~7KB, required=[presentation: u:2,v:3,w:4]) ├── G1: (distinct-on G2 G3 cols=(2-4)) (distinct-on G2 G3 cols=(2-4),ordering=+2,+3,+4) (distinct-on G2 G3 cols=(2-4),ordering=+4,+3,+2) (distinct-on G2 G3 cols=(2-4),ordering=+3,+4) │ └── [presentation: u:2,v:3,w:4] │ ├── best: (distinct-on G2="[ordering: +2,+3,+4]" G3 cols=(2-4),ordering=+2,+3,+4) diff --git a/pkg/sql/opt/xform/testdata/rules/join b/pkg/sql/opt/xform/testdata/rules/join index 1efed71a3beb..5a684c10840b 100644 --- a/pkg/sql/opt/xform/testdata/rules/join +++ b/pkg/sql/opt/xform/testdata/rules/join @@ -1249,7 +1249,7 @@ New expression 2 of 2: memo expect=ReorderJoins SELECT * FROM abc JOIN xyz ON a=z ---- -memo (optimized, ~13KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) +memo (optimized, ~14KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) ├── G1: (inner-join G2 G3 G4) (inner-join G3 G2 G4) (merge-join G2 G3 G5 inner-join,+1,+9) (lookup-join G3 G5 abc@ab,keyCols=[9],outCols=(1-3,7-9)) │ └── [presentation: a:1,b:2,c:3,x:7,y:8,z:9] │ ├── best: (inner-join G2 G3 G4) @@ -1493,7 +1493,7 @@ right-join (hash) memo SELECT * FROM abc RIGHT OUTER JOIN xyz ON a=z ---- -memo (optimized, ~13KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) +memo (optimized, ~14KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) ├── G1: (left-join G2 G3 G4) (right-join G3 G2 G4) (lookup-join G2 G5 abc@ab,keyCols=[9],outCols=(1-3,7-9)) (merge-join G3 G2 G5 right-join,+1,+9) │ └── [presentation: a:1,b:2,c:3,x:7,y:8,z:9] │ ├── best: (left-join G2 G3 G4) @@ -1823,7 +1823,7 @@ inner-join (merge) memo SELECT * FROM abc JOIN xyz ON a=x ---- -memo (optimized, ~15KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) +memo (optimized, ~16KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) ├── G1: (inner-join G2 G3 G4) (inner-join G3 G2 G4) (merge-join G2 G3 G5 inner-join,+1,+7) (lookup-join G2 G5 xyz@xy,keyCols=[1],outCols=(1-3,7-9)) (merge-join G3 G2 G5 inner-join,+7,+1) (lookup-join G3 G5 abc@ab,keyCols=[7],outCols=(1-3,7-9)) │ └── [presentation: a:1,b:2,c:3,x:7,y:8,z:9] │ ├── best: (merge-join G3="[ordering: +7]" G2="[ordering: +1]" G5 inner-join,+7,+1) @@ -1874,7 +1874,7 @@ memo (optimized, ~11KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) memo set=(optimizer_merge_joins_enabled=false) expect-not=GenerateMergeJoins SELECT * FROM abc JOIN xyz ON a=x ---- -memo (optimized, ~14KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) +memo (optimized, ~15KB, required=[presentation: a:1,b:2,c:3,x:7,y:8,z:9]) ├── G1: (inner-join G2 G3 G4) (inner-join G3 G2 G4) (lookup-join G2 G5 xyz@xy,keyCols=[1],outCols=(1-3,7-9)) (lookup-join G3 G5 abc@ab,keyCols=[7],outCols=(1-3,7-9)) │ └── [presentation: a:1,b:2,c:3,x:7,y:8,z:9] │ ├── best: (inner-join G3 G2 G4) diff --git a/pkg/sql/opt/xform/testdata/rules/select b/pkg/sql/opt/xform/testdata/rules/select index 4b1a2c6bfc73..993c7f0facfc 100644 --- a/pkg/sql/opt/xform/testdata/rules/select +++ b/pkg/sql/opt/xform/testdata/rules/select @@ -281,7 +281,7 @@ CREATE INDEX idx2 ON p (s) WHERE i > 0 memo expect=GeneratePartialIndexScans SELECT * FROM p WHERE i > 0 AND s = 'foo' ---- -memo (optimized, ~18KB, required=[presentation: k:1,i:2,f:3,s:4,b:5]) +memo (optimized, ~19KB, required=[presentation: k:1,i:2,f:3,s:4,b:5]) ├── G1: (select G2 G3) (index-join G4 p,cols=(1-5)) (index-join G5 p,cols=(1-5)) (index-join G6 p,cols=(1-5)) (index-join G7 p,cols=(1-5)) │ └── [presentation: k:1,i:2,f:3,s:4,b:5] │ ├── best: (index-join G4 p,cols=(1-5)) diff --git a/pkg/sql/opt/xform/testdata/rules/set b/pkg/sql/opt/xform/testdata/rules/set index 05704de1137c..e5e1f3d10206 100644 --- a/pkg/sql/opt/xform/testdata/rules/set +++ b/pkg/sql/opt/xform/testdata/rules/set @@ -21,7 +21,7 @@ CREATE TABLE kuvw ( memo expect=GenerateStreamingSetOp SELECT u,v,w FROM kuvw UNION SELECT w,v,u FROM kuvw ---- -memo (optimized, ~11KB, required=[presentation: u:13,v:14,w:15]) +memo (optimized, ~12KB, required=[presentation: u:13,v:14,w:15]) ├── G1: (union G2 G3) (union G2 G3 ordering=+13,+14,+15) (union G2 G3 ordering=+15,+14,+13) (union G2 G3 ordering=+14,+15,+13) (union G2 G3 ordering=+14,+13,+15) │ └── [presentation: u:13,v:14,w:15] │ ├── best: (union G2="[ordering: +2,+3,+4]" G3="[ordering: +10,+9,+8]" ordering=+13,+14,+15) diff --git a/pkg/sql/parser/sql.y b/pkg/sql/parser/sql.y index b4974dff0c15..3dc5e3dd7862 100644 --- a/pkg/sql/parser/sql.y +++ b/pkg/sql/parser/sql.y @@ -958,7 +958,7 @@ func (u *sqlSymUnion) triggerForEach() tree.TriggerForEach { // Ordinary key words in alphabetical order. %token ABORT ABSOLUTE ACCESS ACTION ADD ADMIN AFTER AGGREGATE %token ALL ALTER ALWAYS ANALYSE ANALYZE AND AND_AND ANY ANNOTATE_TYPE ARRAY AS ASC AS_JSON AT_AT -%token ASENSITIVE ASYMMETRIC AT ATOMIC ATTRIBUTE AUTHORIZATION AUTOMATIC AVAILABILITY +%token ASENSITIVE ASYMMETRIC AT ATOMIC ATTRIBUTE AUTHORIZATION AUTOMATIC AVAILABILITY AVOID_FULL_SCAN %token BACKUP BACKUPS BACKWARD BATCH BEFORE BEGIN BETWEEN BIGINT BIGSERIAL BINARY BIT %token BUCKET_COUNT @@ -14248,6 +14248,10 @@ index_flags_param: { $$.val = &tree.IndexFlags{NoFullScan: true} } +| AVOID_FULL_SCAN + { + $$.val = &tree.IndexFlags{AvoidFullScan: true} + } | IGNORE_FOREIGN_KEYS { /* SKIP DOC */ @@ -14337,6 +14341,7 @@ opt_index_flags: // '{' NO_INDEX_JOIN [, ...] '}' // '{' NO_ZIGZAG_JOIN [, ...] '}' // '{' NO_FULL_SCAN [, ...] '}' +// '{' AVOID_FULL_SCAN [, ...] '}' // '{' IGNORE_FOREIGN_KEYS [, ...] '}' // '{' FORCE_ZIGZAG = [, ...] '}' // @@ -17819,6 +17824,7 @@ unreserved_keyword: | ATTRIBUTE | AUTOMATIC | AVAILABILITY +| AVOID_FULL_SCAN | BACKUP | BACKUPS | BACKWARD @@ -18320,6 +18326,7 @@ bare_label_keywords: | AUTHORIZATION | AUTOMATIC | AVAILABILITY +| AVOID_FULL_SCAN | BACKUP | BACKUPS | BACKWARD diff --git a/pkg/sql/parser/testdata/hints b/pkg/sql/parser/testdata/hints index 82f3c57a4a99..98f8d37b7cef 100644 --- a/pkg/sql/parser/testdata/hints +++ b/pkg/sql/parser/testdata/hints @@ -46,6 +46,14 @@ SELECT ('a') FROM t@{NO_FULL_SCAN} -- fully parenthesized SELECT '_' FROM t@{NO_FULL_SCAN} -- literals removed SELECT 'a' FROM _@{NO_FULL_SCAN} -- identifiers removed +parse +SELECT 'a' FROM t@{AVOID_FULL_SCAN} +---- +SELECT 'a' FROM t@{AVOID_FULL_SCAN} +SELECT ('a') FROM t@{AVOID_FULL_SCAN} -- fully parenthesized +SELECT '_' FROM t@{AVOID_FULL_SCAN} -- literals removed +SELECT 'a' FROM _@{AVOID_FULL_SCAN} -- identifiers removed + parse SELECT 'a' FROM t@{IGNORE_FOREIGN_KEYS} ---- diff --git a/pkg/sql/sem/tree/select.go b/pkg/sql/sem/tree/select.go index 40c16ad8fe78..121dc1a8b787 100644 --- a/pkg/sql/sem/tree/select.go +++ b/pkg/sql/sem/tree/select.go @@ -311,6 +311,7 @@ type FamilyID = catid.FamilyID // - NO_INDEX_JOIN // - NO_ZIGZAG_JOIN // - NO_FULL_SCAN +// - AVOID_FULL_SCAN // - IGNORE_FOREIGN_KEYS // - FORCE_INVERTED_INDEX // - FORCE_ZIGZAG @@ -330,6 +331,8 @@ type IndexFlags struct { NoZigzagJoin bool // NoFullScan indicates we should constrain this scan. NoFullScan bool + // AvoidFullScan indicates we should constrain this scan if possible. + AvoidFullScan bool // IgnoreForeignKeys disables optimizations based on outbound foreign key // references from this table. This is useful in particular for scrub queries // used to verify the consistency of foreign key relations. @@ -372,6 +375,9 @@ func (ih *IndexFlags) CombineWith(other *IndexFlags) error { if ih.NoFullScan && other.NoFullScan { return errors.New("NO_FULL_SCAN specified multiple times") } + if ih.AvoidFullScan && other.AvoidFullScan { + return errors.New("AVOID_FULL_SCAN specified multiple times") + } if ih.IgnoreForeignKeys && other.IgnoreForeignKeys { return errors.New("IGNORE_FOREIGN_KEYS specified multiple times") } @@ -385,6 +391,7 @@ func (ih *IndexFlags) CombineWith(other *IndexFlags) error { result.NoIndexJoin = ih.NoIndexJoin || other.NoIndexJoin result.NoZigzagJoin = ih.NoZigzagJoin || other.NoZigzagJoin result.NoFullScan = ih.NoFullScan || other.NoFullScan + result.AvoidFullScan = ih.AvoidFullScan || other.AvoidFullScan result.IgnoreForeignKeys = ih.IgnoreForeignKeys || other.IgnoreForeignKeys result.IgnoreUniqueWithoutIndexKeys = ih.IgnoreUniqueWithoutIndexKeys || other.IgnoreUniqueWithoutIndexKeys @@ -525,6 +532,11 @@ func (ih *IndexFlags) Format(ctx *FmtCtx) { ctx.WriteString("NO_FULL_SCAN") } + if ih.AvoidFullScan { + sep() + ctx.WriteString("AVOID_FULL_SCAN") + } + if ih.IgnoreForeignKeys { sep() ctx.WriteString("IGNORE_FOREIGN_KEYS") @@ -572,9 +584,9 @@ func (ih *IndexFlags) Format(ctx *FmtCtx) { } func (ih *IndexFlags) indexOnlyHint() bool { - return !ih.NoIndexJoin && !ih.NoZigzagJoin && !ih.NoFullScan && !ih.IgnoreForeignKeys && - !ih.IgnoreUniqueWithoutIndexKeys && ih.Direction == 0 && !ih.ForceInvertedIndex && - !ih.zigzagForced() && ih.FamilyID == nil + return !ih.NoIndexJoin && !ih.NoZigzagJoin && !ih.NoFullScan && !ih.AvoidFullScan && + !ih.IgnoreForeignKeys && !ih.IgnoreUniqueWithoutIndexKeys && ih.Direction == 0 && + !ih.ForceInvertedIndex && !ih.zigzagForced() && ih.FamilyID == nil } func (ih *IndexFlags) zigzagForced() bool {