From d2eac1e03aeaf6460070ada635f2f03fc3655bcc Mon Sep 17 00:00:00 2001 From: Rebecca Taft Date: Tue, 18 Apr 2023 20:34:23 -0500 Subject: [PATCH] sql: support setting index visibility in CREATE INDEX and CREATE TABLE This commit adds support for CREATE INDEX ... VISIBILITY ... as well as CREATE TABLE ... (... INDEX (...) VISIBILITY ...). This allows users to set the index visibility to any float [0.0, 1.0] upon creation of the index. ALTER INDEX ... VISIBILITY ... was previously supported in #87301. Informs #82363 Release note (sql change): CREATE INDEX ... VISIBILITY ... as well as CREATE TABLE ... (... INDEX (...) VISIBILITY ...) are now supported. This allows a user to set the index visibility to any visibility within [0.0, 1.0]. Visibility 0.0 means the index is not visible to the optimizer, while visibility 1.0 means the index is fully visible. A value in the range (0.0, 1.0) means the index will be visibile to the corresponding fraction of queries. --- docs/generated/sql/bnf/stmt_block.bnf | 1 + .../execbuilder/testdata/not_visible_index | 66 +++++++++++++++---- pkg/sql/parser/sql.y | 12 ++++ pkg/sql/parser/testdata/create_index | 8 +++ pkg/sql/parser/testdata/create_table | 8 +++ 5 files changed, 82 insertions(+), 13 deletions(-) diff --git a/docs/generated/sql/bnf/stmt_block.bnf b/docs/generated/sql/bnf/stmt_block.bnf index e038258e218c..6e80662fd918 100644 --- a/docs/generated/sql/bnf/stmt_block.bnf +++ b/docs/generated/sql/bnf/stmt_block.bnf @@ -2432,6 +2432,7 @@ opt_index_visible ::= 'NOT' 'VISIBLE' | 'INVISIBLE' | 'VISIBLE' + | 'VISIBILITY' 'FCONST' | opt_schema_name ::= diff --git a/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index b/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index index 4e983b079604..083f264a8959 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index +++ b/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index @@ -1532,11 +1532,6 @@ statement ok CREATE INDEX k1_idx on t(k); ALTER INDEX k1_idx INVISIBLE -# Create an index with partial visibility. -statement ok -CREATE INDEX v_idx on t(v); -ALTER INDEX v_idx VISIBILITY 0.5 - query TTBITTTBBBF colnames SELECT * FROM [SHOW INDEX FROM t] ---- @@ -1549,6 +1544,51 @@ t k_idx true 1 k k ASC t k_idx true 2 p p ASC false true false 0 t k1_idx true 1 k k ASC false false false 0 t k1_idx true 2 p p ASC false true false 0 + +statement ok +DROP TABLE t + +# Create an index with partial visibility. +statement ok +CREATE TABLE t ( + p INT PRIMARY KEY, + k INT, + v STRING, + INDEX p_idx (p) VISIBILITY 0.75, + FAMILY (p, k, v) +) + +statement ok +CREATE INDEX k_idx on t(k) VISIBILITY 0.25 + +statement ok +CREATE INDEX v_idx on t(v); +ALTER INDEX v_idx VISIBILITY 0.5 + +query TT +SHOW CREATE TABLE t +---- +t CREATE TABLE public.t ( + p INT8 NOT NULL, + k INT8 NULL, + v STRING NULL, + CONSTRAINT t_pkey PRIMARY KEY (p ASC), + INDEX p_idx (p ASC) VISIBILITY 0.75, + INDEX k_idx (k ASC) VISIBILITY 0.25, + INDEX v_idx (v ASC) VISIBILITY 0.50, + FAMILY fam_0_p_k_v (p, k, v) + ) + +query TTBITTTBBBF colnames +SELECT * FROM [SHOW INDEX FROM t] +---- +table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible visibility +t t_pkey false 1 p p ASC false false true 1 +t t_pkey false 2 k k N/A true false true 1 +t t_pkey false 3 v v N/A true false true 1 +t p_idx true 1 p p ASC false false false 0.75 +t k_idx true 1 k k ASC false false false 0.25 +t k_idx true 2 p p ASC false true false 0.25 t v_idx true 1 v v ASC false false false 0.5 t v_idx true 2 p p ASC false true false 0.5 @@ -1562,13 +1602,13 @@ EXPLAIN SELECT * FROM t WHERE v = 'foo' distribution: local vectorized: true · -• index join -│ table: t@t_pkey +• filter +│ filter: v = 'foo' │ └── • scan missing stats - table: t@v_idx - spans: [/'foo' - /'foo'] + table: t@t_pkey + spans: FULL SCAN statement ok SET testing_optimizer_random_seed=3164997759865821235 @@ -1579,13 +1619,13 @@ EXPLAIN SELECT * FROM t WHERE v = 'foo' distribution: local vectorized: true · -• filter -│ filter: v = 'foo' +• index join +│ table: t@t_pkey │ └── • scan missing stats - table: t@t_pkey - spans: FULL SCAN + table: t@v_idx + spans: [/'foo' - /'foo'] statement ok RESET testing_optimizer_random_seed diff --git a/pkg/sql/parser/sql.y b/pkg/sql/parser/sql.y index 60e6d36597b7..542f91eeb62c 100644 --- a/pkg/sql/parser/sql.y +++ b/pkg/sql/parser/sql.y @@ -10810,6 +10810,18 @@ opt_index_visible: { $$.val = tree.NewNumVal(constant.MakeFloat64(0.0), "0.0", false /*negative*/) } +| VISIBILITY FCONST + { + visibilityConst, _ := constant.Float64Val($2.numVal().AsConstantValue()) + if visibilityConst < 0.0 || visibilityConst > 1.0 { + sqllex.Error("index visibility must be between 0 and 1") + return 1 + } + invisibilityConst := 1.0 - visibilityConst + invisibilityStr := fmt.Sprintf("%.2f", invisibilityConst) + treeNumVal := tree.NewNumVal(constant.MakeFloat64(invisibilityConst), invisibilityStr, false /*negative*/) + $$.val = treeNumVal + } | /* EMPTY */ { $$.val = tree.NewNumVal(constant.MakeFloat64(0.0), "0.0", false /*negative*/) diff --git a/pkg/sql/parser/testdata/create_index b/pkg/sql/parser/testdata/create_index index 7872ad86d20d..f056d1ea4461 100644 --- a/pkg/sql/parser/testdata/create_index +++ b/pkg/sql/parser/testdata/create_index @@ -452,3 +452,11 @@ CREATE UNIQUE INDEX IF NOT EXISTS a ON b (c) WHERE d > 3 NOT VISIBLE CREATE UNIQUE INDEX IF NOT EXISTS a ON b (c) WHERE ((d) > (3)) NOT VISIBLE -- fully parenthesized CREATE UNIQUE INDEX IF NOT EXISTS a ON b (c) WHERE d > _ NOT VISIBLE -- literals removed CREATE UNIQUE INDEX IF NOT EXISTS _ ON _ (_) WHERE _ > 3 NOT VISIBLE -- identifiers removed + +parse +CREATE INDEX a ON b (c) VISIBILITY 0.2 +---- +CREATE INDEX a ON b (c) VISIBILITY 0.20 -- normalized! +CREATE INDEX a ON b (c) VISIBILITY 0.20 -- fully parenthesized +CREATE INDEX a ON b (c) VISIBILITY 0.20 -- literals removed +CREATE INDEX _ ON _ (_) VISIBILITY 0.20 -- identifiers removed diff --git a/pkg/sql/parser/testdata/create_table b/pkg/sql/parser/testdata/create_table index a498f86c4391..9b4c29795bf7 100644 --- a/pkg/sql/parser/testdata/create_table +++ b/pkg/sql/parser/testdata/create_table @@ -2451,6 +2451,14 @@ CREATE TABLE a (b INT8, c STRING, INVERTED INDEX (b ASC, c DESC) WHERE ((c) > (3 CREATE TABLE a (b INT8, c STRING, INVERTED INDEX (b ASC, c DESC) WHERE c > _ NOT VISIBLE) -- literals removed CREATE TABLE _ (_ INT8, _ STRING, INVERTED INDEX (_ ASC, _ DESC) WHERE _ > 3 NOT VISIBLE) -- identifiers removed +parse +CREATE TABLE a (b INT8, c STRING, INDEX (b ASC, c DESC) STORING (c) VISIBILITY 0.2) +---- +CREATE TABLE a (b INT8, c STRING, INDEX (b ASC, c DESC) STORING (c) VISIBILITY 0.20) -- normalized! +CREATE TABLE a (b INT8, c STRING, INDEX (b ASC, c DESC) STORING (c) VISIBILITY 0.20) -- fully parenthesized +CREATE TABLE a (b INT8, c STRING, INDEX (b ASC, c DESC) STORING (c) VISIBILITY 0.20) -- literals removed +CREATE TABLE _ (_ INT8, _ STRING, INDEX (_ ASC, _ DESC) STORING (_) VISIBILITY 0.20) -- identifiers removed + # Creating an invisible unique index inside a table definition is supported by # the grammar rule, but the parser will throw an error for the following # statement. This is because the parser is doing a round trip in