Skip to content

Commit

Permalink
sql: adds is_visible to indexes info table
Browse files Browse the repository at this point in the history
This PR adds a new column `is_visible` to `crdb_internal.table_indexes` and
`information_schema.statistics`. It also adds a new column `visible` to the
output of following SQL statements:

```
SHOW INDEX FROM (table_name)
SHOW INDEXES FROM (table_name)
SHOW KEYS FROM (table_name)
SHOW INDEX FROM DATABASE (database_name)
SHOW INDEXES FROM DATABASE (database_name)
SHOW KEYS FROM DATABASE (database_name)
```

Since the not visible index feature has not been introduced yet, it is expected
for all test cases to output `true` for all `is_visible` or `visible` columns.

See also: #83471

Assists: #72576

Release note (sql change): A new column `is_visible` has been added to the table
`crdb_internal.table_indexes` and `information_schema.statistics`. A new column
`visible` has also been added to the output of `SHOW INDEX`, `SHOW INDEXES`, and
`SHOW KEYS`. The `is_visible` or `visible` column indicates whether the index is
visible to the optimizer.
  • Loading branch information
wenyihu6 committed Jul 21, 2022
1 parent a4610f6 commit 6300c57
Show file tree
Hide file tree
Showing 26 changed files with 456 additions and 436 deletions.
4 changes: 2 additions & 2 deletions pkg/ccl/logictestccl/testdata/logic_test/crdb_internal_tenant
Original file line number Diff line number Diff line change
Expand Up @@ -280,10 +280,10 @@ SELECT * FROM crdb_internal.table_columns WHERE descriptor_name = ''
----
descriptor_id descriptor_name column_id column_name column_type nullable default_expr hidden

query ITITTBBBIT colnames
query ITITTBBBBIT colnames
SELECT * FROM crdb_internal.table_indexes WHERE descriptor_name = ''
----
descriptor_id descriptor_name index_id index_name index_type is_unique is_inverted is_sharded shard_bucket_count created_at
descriptor_id descriptor_name index_id index_name index_type is_unique is_inverted is_sharded is_visible shard_bucket_count created_at

query ITITTITTB colnames
SELECT * FROM crdb_internal.index_columns WHERE descriptor_name = ''
Expand Down
2 changes: 2 additions & 0 deletions pkg/sql/crdb_internal.go
Original file line number Diff line number Diff line change
Expand Up @@ -2781,6 +2781,7 @@ CREATE TABLE crdb_internal.table_indexes (
is_unique BOOL NOT NULL,
is_inverted BOOL NOT NULL,
is_sharded BOOL NOT NULL,
is_visible BOOL NOT NULL,
shard_bucket_count INT,
created_at TIMESTAMP
)
Expand Down Expand Up @@ -2826,6 +2827,7 @@ CREATE TABLE crdb_internal.table_indexes (
tree.MakeDBool(tree.DBool(idx.IsUnique())),
tree.MakeDBool(idx.GetType() == descpb.IndexDescriptor_INVERTED),
tree.MakeDBool(tree.DBool(idx.IsSharded())),
tree.MakeDBool(tree.DBool(!idx.IsNotVisible())),
shardBucketCnt,
createdAt,
)
Expand Down
13 changes: 11 additions & 2 deletions pkg/sql/delegate/show_database_indexes.go
Original file line number Diff line number Diff line change
Expand Up @@ -16,9 +16,17 @@ import (
"github.com/cockroachdb/cockroach/pkg/sql/sem/tree"
)

// delegateShowDatabaseIndexes implements SHOW INDEX FROM DATABASE, SHOW INDEXES
// FROM DATABASE, SHOW KEYS FROM DATABASE which returns all the indexes in the
// given or current database.
func (d *delegator) delegateShowDatabaseIndexes(
n *tree.ShowDatabaseIndexes,
) (tree.Statement, error) {
name, err := d.getSpecifiedOrCurrentDatabase(n.Database)
if err != nil {
return nil, err
}

getAllIndexesQuery := `
SELECT
table_name,
Expand All @@ -28,7 +36,8 @@ SELECT
column_name,
direction,
storing::BOOL,
implicit::BOOL`
implicit::BOOL,
is_visible::BOOL AS visible`

if n.WithComment {
getAllIndexesQuery += `,
Expand All @@ -45,5 +54,5 @@ FROM
statistics.index_name = pg_class.relname`
}

return parse(fmt.Sprintf(getAllIndexesQuery, n.Database.String()))
return parse(fmt.Sprintf(getAllIndexesQuery, name.String()))
}
7 changes: 5 additions & 2 deletions pkg/sql/delegate/show_table.go
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,8 @@ ORDER BY
return d.showTableDetails(n.Name, showCreateQuery)
}

// delegateShowIndexes implements SHOW INDEX FROM, SHOW INDEXES FROM, SHOW KEYS
// FROM which returns all the indexes in the given table.
func (d *delegator) delegateShowIndexes(n *tree.ShowIndexes) (tree.Statement, error) {
sqltelemetry.IncrementShowCounter(sqltelemetry.Indexes)
getIndexesQuery := `
Expand All @@ -111,7 +113,8 @@ SELECT
column_name,
direction,
storing::BOOL,
implicit::BOOL`
implicit::BOOL,
is_visible::BOOL AS visible`

if n.WithComment {
getIndexesQuery += `,
Expand All @@ -135,7 +138,7 @@ WHERE
AND table_schema=%[5]s
AND table_name=%[2]s
ORDER BY
1, 2, 3, 4, 5, 6, 7, 8;`
1, 2, 4;`

return d.showTableDetails(n.Table, getIndexesQuery)
}
Expand Down
10 changes: 5 additions & 5 deletions pkg/sql/descriptor_mutation_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -1051,11 +1051,11 @@ CREATE TABLE t.test (a STRING PRIMARY KEY, b STRING, c STRING, INDEX foo (c));
mt.CheckQueryResults(t,
"SHOW INDEXES FROM t.test",
[][]string{
{"test", "test_pkey", "false", "1", "a", "ASC", "false", "false"},
{"test", "test_pkey", "false", "2", "b", "N/A", "true", "false"},
{"test", "test_pkey", "false", "3", "d", "N/A", "true", "false"},
{"test", "ufo", "true", "1", "d", "ASC", "false", "false"},
{"test", "ufo", "true", "2", "a", "ASC", "false", "true"},
{"test", "test_pkey", "false", "1", "a", "ASC", "false", "false", "true"},
{"test", "test_pkey", "false", "2", "b", "N/A", "true", "false", "true"},
{"test", "test_pkey", "false", "3", "d", "N/A", "true", "false", "true"},
{"test", "ufo", "true", "1", "d", "ASC", "false", "false", "true"},
{"test", "ufo", "true", "2", "a", "ASC", "false", "true", "true"},
},
)

Expand Down
27 changes: 14 additions & 13 deletions pkg/sql/information_schema.go
Original file line number Diff line number Diff line change
Expand Up @@ -1144,19 +1144,20 @@ var informationSchemaStatisticsTable = virtualSchemaTable{
direction tree.Datum, isStored, isImplicit bool,
) error {
return addRow(
dbNameStr, // table_catalog
scNameStr, // table_schema
tbNameStr, // table_name
yesOrNoDatum(!index.IsUnique()), // non_unique
scNameStr, // index_schema
tree.NewDString(index.GetName()), // index_name
tree.NewDInt(tree.DInt(sequence)), // seq_in_index
tree.NewDString(colName), // column_name
tree.DNull, // collation
tree.DNull, // cardinality
direction, // direction
yesOrNoDatum(isStored), // storing
yesOrNoDatum(isImplicit), // implicit
dbNameStr, // table_catalog
scNameStr, // table_schema
tbNameStr, // table_name
yesOrNoDatum(!index.IsUnique()), // non_unique
scNameStr, // index_schema
tree.NewDString(index.GetName()), // index_name
tree.NewDInt(tree.DInt(sequence)), // seq_in_index
tree.NewDString(colName), // column_name
tree.DNull, // collation
tree.DNull, // cardinality
direction, // direction
yesOrNoDatum(isStored), // storing
yesOrNoDatum(isImplicit), // implicit
yesOrNoDatum(!index.IsNotVisible()), // is_visible
)
}

Expand Down
48 changes: 24 additions & 24 deletions pkg/sql/logictest/testdata/logic_test/alter_table
Original file line number Diff line number Diff line change
Expand Up @@ -49,17 +49,17 @@ ALTER TABLE t ADD CONSTRAINT foo UNIQUE (b)
statement error pq: multiple primary keys for table "t" are not allowed
ALTER TABLE t ADD CONSTRAINT bar PRIMARY KEY (b)

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM t
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
t foo false 1 b ASC false false
t foo false 2 a ASC true true
t t_f_idx true 1 f ASC false false
t t_f_idx true 2 a ASC false true
t t_pkey false 1 a ASC false false
t t_pkey false 2 f N/A true false
t t_pkey false 3 b N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
t foo false 1 b ASC false false true
t foo false 2 a ASC true true true
t t_f_idx true 1 f ASC false false true
t t_f_idx true 2 a ASC false true true
t t_pkey false 1 a ASC false false true
t t_pkey false 2 f N/A true false true
t t_pkey false 3 b N/A true false true

query III
SELECT * FROM t
Expand Down Expand Up @@ -226,16 +226,16 @@ LIMIT 2
SCHEMA CHANGE GC GC for DROP INDEX test.public.t@foo CASCADE root running waiting for GC TTL 0 ·
SCHEMA CHANGE DROP INDEX test.public.t@foo CASCADE root succeeded NULL 1 ·

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM t
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
t t_f_idx true 1 f ASC false false
t t_f_idx true 2 a ASC false true
t t_pkey false 1 a ASC false false
t t_pkey false 2 f N/A true false
t t_pkey false 3 b N/A true false
t t_pkey false 4 c N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
t t_f_idx true 1 f ASC false false true
t t_f_idx true 2 a ASC false true true
t t_pkey false 1 a ASC false false true
t t_pkey false 2 f N/A true false true
t t_pkey false 3 b N/A true false true
t t_pkey false 4 c N/A true false true

statement ok
ALTER TABLE t DROP b, DROP c
Expand Down Expand Up @@ -382,15 +382,15 @@ ALTER TABLE t DROP COLUMN g CASCADE
statement ok
ALTER TABLE o DROP COLUMN h

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM o
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
o o_pkey false 1 rowid ASC false false
o o_pkey false 2 gf N/A true false
o o_pkey false 3 i N/A true false
o oi true 1 i ASC false false
o oi true 2 rowid ASC false true
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
o o_pkey false 1 rowid ASC false false true
o o_pkey false 2 gf N/A true false true
o o_pkey false 3 i N/A true false true
o oi true 1 i ASC false false true
o oi true 2 rowid ASC false true true

statement ok
ALTER TABLE t ADD f INT CHECK (f > 1)
Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/logictest/testdata/logic_test/crdb_internal
Original file line number Diff line number Diff line change
Expand Up @@ -400,10 +400,10 @@ SELECT * FROM crdb_internal.table_columns WHERE descriptor_name = ''
----
descriptor_id descriptor_name column_id column_name column_type nullable default_expr hidden

query ITITTBBBIT colnames
query ITITTBBBBIT colnames
SELECT * FROM crdb_internal.table_indexes WHERE descriptor_name = ''
----
descriptor_id descriptor_name index_id index_name index_type is_unique is_inverted is_sharded shard_bucket_count created_at
descriptor_id descriptor_name index_id index_name index_type is_unique is_inverted is_sharded is_visible shard_bucket_count created_at

query ITITTITTB colnames
SELECT * FROM crdb_internal.index_columns WHERE descriptor_name = ''
Expand Down
64 changes: 32 additions & 32 deletions pkg/sql/logictest/testdata/logic_test/create_index
Original file line number Diff line number Diff line change
Expand Up @@ -23,29 +23,29 @@ CREATE INDEX bar ON t (c)
statement error index \"bar\" contains duplicate column \"b\"
CREATE INDEX bar ON t (b, b);

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM t
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
t foo true 1 b ASC false false
t foo true 2 a ASC false true
t t_pkey false 1 a ASC false false
t t_pkey false 2 b N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
t foo true 1 b ASC false false true
t foo true 2 a ASC false true true
t t_pkey false 1 a ASC false false true
t t_pkey false 2 b N/A true false true

statement ok
INSERT INTO t VALUES (2,1)

statement error pgcode 23505 violates unique constraint "bar"
CREATE UNIQUE INDEX bar ON t (b)

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM t
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
t foo true 1 b ASC false false
t foo true 2 a ASC false true
t t_pkey false 1 a ASC false false
t t_pkey false 2 b N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
t foo true 1 b ASC false false true
t foo true 2 a ASC false true true
t t_pkey false 1 a ASC false false true
t t_pkey false 2 b N/A true false true

# test for DESC index

Expand All @@ -68,18 +68,18 @@ CREATE INDEX b_desc ON t (b DESC)
statement ok
CREATE INDEX b_asc ON t (b ASC, c DESC)

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM t
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
t b_asc true 1 b ASC false false
t b_asc true 2 c DESC false false
t b_asc true 3 a ASC false true
t b_desc true 1 b DESC false false
t b_desc true 2 a ASC false true
t t_pkey false 1 a ASC false false
t t_pkey false 2 b N/A true false
t t_pkey false 3 c N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
t b_asc true 1 b ASC false false true
t b_asc true 2 c DESC false false true
t b_asc true 3 a ASC false true true
t b_desc true 1 b DESC false false true
t b_desc true 2 a ASC false true true
t t_pkey false 1 a ASC false false true
t t_pkey false 2 b N/A true false true
t t_pkey false 3 c N/A true false true

statement error pgcode 42P01 relation "foo" does not exist
CREATE INDEX fail ON foo (b DESC)
Expand All @@ -100,12 +100,12 @@ CREATE INDEX foo ON privs (b)

user root

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM privs
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
privs privs_pkey false 1 a ASC false false
privs privs_pkey false 2 b N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
privs privs_pkey false 1 a ASC false false true
privs privs_pkey false 2 b N/A true false true

statement ok
GRANT CREATE ON privs TO testuser
Expand All @@ -115,14 +115,14 @@ user testuser
statement ok
CREATE INDEX foo ON privs (b)

query TTBITTBB colnames
query TTBITTBBB colnames
SHOW INDEXES FROM privs
----
table_name index_name non_unique seq_in_index column_name direction storing implicit
privs foo true 1 b ASC false false
privs foo true 2 a ASC false true
privs privs_pkey false 1 a ASC false false
privs privs_pkey false 2 b N/A true false
table_name index_name non_unique seq_in_index column_name direction storing implicit visible
privs foo true 1 b ASC false false true
privs foo true 2 a ASC false true true
privs privs_pkey false 1 a ASC false false true
privs privs_pkey false 2 b N/A true false true


user root
Expand Down
8 changes: 6 additions & 2 deletions pkg/sql/logictest/testdata/logic_test/create_statements
Original file line number Diff line number Diff line change
Expand Up @@ -1540,6 +1540,7 @@ CREATE TABLE crdb_internal.table_indexes (
is_unique BOOL NOT NULL,
is_inverted BOOL NOT NULL,
is_sharded BOOL NOT NULL,
is_visible BOOL NOT NULL,
shard_bucket_count INT8 NULL,
created_at TIMESTAMP NULL
) CREATE TABLE crdb_internal.table_indexes (
Expand All @@ -1551,6 +1552,7 @@ CREATE TABLE crdb_internal.table_indexes (
is_unique BOOL NOT NULL,
is_inverted BOOL NOT NULL,
is_sharded BOOL NOT NULL,
is_visible BOOL NOT NULL,
shard_bucket_count INT8 NULL,
created_at TIMESTAMP NULL
) {} {}
Expand Down Expand Up @@ -3298,7 +3300,8 @@ CREATE TABLE information_schema.statistics (
cardinality INT8 NULL,
direction STRING NOT NULL,
storing STRING NOT NULL,
implicit STRING NOT NULL
implicit STRING NOT NULL,
is_visible STRING NOT NULL
) CREATE TABLE information_schema.statistics (
table_catalog STRING NOT NULL,
table_schema STRING NOT NULL,
Expand All @@ -3312,7 +3315,8 @@ CREATE TABLE information_schema.statistics (
cardinality INT8 NULL,
direction STRING NOT NULL,
storing STRING NOT NULL,
implicit STRING NOT NULL
implicit STRING NOT NULL,
is_visible STRING NOT NULL
) {} {}
CREATE TABLE information_schema.table_constraints (
constraint_catalog STRING NOT NULL,
Expand Down
Loading

0 comments on commit 6300c57

Please sign in to comment.