From b934a9454b4aa35186ff25363aa28c0c634d0209 Mon Sep 17 00:00:00 2001
From: Rafi Shamim
Date: Tue, 17 Jan 2023 16:57:18 -0500
Subject: [PATCH 1/3] builtins: make pg_get_indexdef handle expression indexes
Release note (bug fix): The pg_get_indexdef was fixed so that it shows
the expression used to define an expression-based index. In addition,
the function was previously including columns stored by the index,
which was incorrect and has now been fixed.
---
.../testdata/logic_test/builtin_function | 5 ++-
.../logictest/testdata/logic_test/pg_builtins | 21 ++++++++++
.../logictest/testdata/logic_test/pg_catalog | 20 +++++-----
pkg/sql/pg_catalog.go | 11 ++++-
pkg/sql/sem/builtins/pg_builtins.go | 40 +++++++------------
5 files changed, 59 insertions(+), 38 deletions(-)
diff --git a/pkg/sql/logictest/testdata/logic_test/builtin_function b/pkg/sql/logictest/testdata/logic_test/builtin_function
index e189e5742b0f..0d5cd8c50020 100644
--- a/pkg/sql/logictest/testdata/logic_test/builtin_function
+++ b/pkg/sql/logictest/testdata/logic_test/builtin_function
@@ -2256,10 +2256,13 @@ SELECT pg_catalog.pg_get_indexdef((SELECT oid from pg_class WHERE relname='pg_in
----
b
+# The empty string should be returned for index 3. Previously, there was a bug
+# where this would return the primary key column name, since the primary key
+# is stored in the index.
query T
SELECT pg_catalog.pg_get_indexdef((SELECT oid from pg_class WHERE relname='pg_indexdef_cols_idx'), 3, false)
----
-rowid
+·
query I
SELECT length(pg_catalog.pg_get_indexdef((SELECT oid from pg_class WHERE relname='pg_indexdef_cols_idx'), 4, false))
diff --git a/pkg/sql/logictest/testdata/logic_test/pg_builtins b/pkg/sql/logictest/testdata/logic_test/pg_builtins
index b0c4b6409b76..ba60e9ab4d3f 100644
--- a/pkg/sql/logictest/testdata/logic_test/pg_builtins
+++ b/pkg/sql/logictest/testdata/logic_test/pg_builtins
@@ -811,3 +811,24 @@ query T
SELECT to_regtype('test_type')
----
test_type
+
+# Test that pg_get_indexdef works for expression indexes.
+statement ok
+CREATE TABLE expr_idx_tbl (id string PRIMARY key, json JSON)
+
+statement ok
+CREATE INDEX expr_idx ON expr_idx_tbl (id, (json->>'bar'), (length(id)))
+
+query T
+SELECT pg_get_indexdef('expr_idx'::regclass::oid)
+----
+CREATE INDEX expr_idx ON test.public.expr_idx_tbl USING btree (id ASC, (json->>'bar'::STRING) ASC, length(id) ASC)
+
+query IT
+SELECT k, pg_get_indexdef('expr_idx'::regclass::oid, k, true) FROM generate_series(0,4) k ORDER BY k
+----
+0 CREATE INDEX expr_idx ON test.public.expr_idx_tbl USING btree (id ASC, (json->>'bar'::STRING) ASC, length(id) ASC)
+1 id
+2 (json->>'bar'::STRING)
+3 (length(id))
+4 ·
diff --git a/pkg/sql/logictest/testdata/logic_test/pg_catalog b/pkg/sql/logictest/testdata/logic_test/pg_catalog
index e99656dd1f2c..a0544fcb7999 100644
--- a/pkg/sql/logictest/testdata/logic_test/pg_catalog
+++ b/pkg/sql/logictest/testdata/logic_test/pg_catalog
@@ -1078,10 +1078,10 @@ SELECT indexrelid, indrelid, indislive, indisreplident, indkey, indcollation, in
FROM pg_catalog.pg_index
WHERE indnkeyatts = 2
----
-indexrelid indrelid indislive indisreplident indkey indcollation indclass indoption indexprs indpred
-3687884464 110 true false 3 4 0 0 0 0 2 2 NULL NULL
-2695335053 114 true false 1 2 3 0 0 0 0 2 1 NULL NULL
-2129466854 120 true false 0 0 3403232968 0 0 0 2 2 (lower(c)) (a + b) NULL
+indexrelid indrelid indislive indisreplident indkey indcollation indclass indoption indexprs indpred
+3687884464 110 true false 3 4 0 0 0 0 2 2 NULL NULL
+2695335053 114 true false 1 2 3 0 0 0 0 2 1 NULL NULL
+2129466854 120 true false 0 0 3403232968 0 0 0 2 2 {(lower(c)),"(a + b)"} NULL
# Index expression elements should have an indkey of 0 and be included in
# indexprs.
@@ -1094,12 +1094,12 @@ JOIN pg_catalog.pg_class c ON i.indexrelid = c.oid
WHERE c.relname LIKE 't6_%'
ORDER BY 1
----
-relname indkey indexprs indpred
-t6_expr_expr1_idx 0 0 (lower(c)) (a + b) NULL
-t6_expr_idx 0 (a + b) NULL
-t6_expr_idx1 0 (m = 'foo'::constraint_db.public.mytype) m = 'foo'::constraint_db.public.mytype
-t6_expr_key 0 (lower(c)) NULL
-t6_pkey 6 NULL NULL
+relname indkey indexprs indpred
+t6_expr_expr1_idx 0 0 {(lower(c)),"(a + b)"} NULL
+t6_expr_idx 0 {"(a + b)"} NULL
+t6_expr_idx1 0 {"(m = 'foo'::constraint_db.public.mytype)"} m = 'foo'::constraint_db.public.mytype
+t6_expr_key 0 {(lower(c))} NULL
+t6_pkey 6 NULL NULL
statement ok
SET DATABASE = system
diff --git a/pkg/sql/pg_catalog.go b/pkg/sql/pg_catalog.go
index 00d7b94931bc..de1042074401 100644
--- a/pkg/sql/pg_catalog.go
+++ b/pkg/sql/pg_catalog.go
@@ -1911,7 +1911,16 @@ https://www.postgresql.org/docs/9.5/catalog-pg-index.html`,
}
indexprs := tree.DNull
if len(exprs) > 0 {
- indexprs = tree.NewDString(strings.Join(exprs, " "))
+ // The column contains multiple elements, but must be stored as a
+ // string. Similar to Postgres, this is a list with one element for
+ // each zero entry in indkey.
+ arr := tree.NewDArray(types.String)
+ for _, expr := range exprs {
+ if err := arr.Append(tree.NewDString(expr)); err != nil {
+ return err
+ }
+ }
+ indexprs = tree.NewDString(tree.AsStringWithFlags(arr, tree.FmtPgwireText))
}
return addRow(
h.IndexOid(table.GetID(), index.GetID()), // indexrelid
diff --git a/pkg/sql/sem/builtins/pg_builtins.go b/pkg/sql/sem/builtins/pg_builtins.go
index 37be57c5f51c..18f8cacfbb6a 100644
--- a/pkg/sql/sem/builtins/pg_builtins.go
+++ b/pkg/sql/sem/builtins/pg_builtins.go
@@ -212,48 +212,36 @@ func makePGGetIndexDef(paramTypes tree.ParamTypes) tree.Overload {
Fn: func(ctx context.Context, evalCtx *eval.Context, args tree.Datums) (tree.Datum, error) {
colNumber := *tree.NewDInt(0)
if len(args) == 3 {
+ // The 1 argument and 3 argument variants are equivalent when column number 0 is passed.
colNumber = *args[1].(*tree.DInt)
}
+ // The 3 argument variant for column number other than 0 returns the column name.
r, err := evalCtx.Planner.QueryRowEx(
ctx, "pg_get_indexdef",
sessiondata.NoSessionDataOverride,
- "SELECT indexdef FROM pg_catalog.pg_indexes WHERE crdb_oid = $1", args[0])
+ `SELECT CASE
+ WHEN $2 = 0 THEN defs.indexdef
+ -- If the column number does not exist in the index we return an empty string.
+ WHEN $2 < 0 OR $2 > array_length(i.indkey, 1) THEN ''
+ WHEN i.indkey[$2-1] = 0 THEN (indexprs::STRING[])[array_position(array_positions(i.indkey, 0), $2)]
+ ELSE a.attname
+ END as pg_get_indexdef
+ FROM pg_catalog.pg_index i
+ LEFT JOIN pg_attribute a ON (a.attrelid = i.indexrelid AND a.attnum = $2)
+ LEFT JOIN pg_indexes defs ON ($2 = 0 AND defs.crdb_oid = i.indexrelid)
+ WHERE i.indexrelid = $1`, args[0], colNumber)
if err != nil {
return nil, err
}
- // If the index does not exist we return null.
if len(r) == 0 {
return tree.DNull, nil
}
- // The 1 argument and 3 argument variants are equivalent when column number 0 is passed.
- if colNumber == 0 {
- return r[0], nil
- }
- // The 3 argument variant for column number other than 0 returns the column name.
- r, err = evalCtx.Planner.QueryRowEx(
- ctx, "pg_get_indexdef",
- sessiondata.NoSessionDataOverride,
- `SELECT ischema.column_name as pg_get_indexdef
- FROM information_schema.statistics AS ischema
- INNER JOIN pg_catalog.pg_indexes AS pgindex
- ON ischema.table_schema = pgindex.schemaname
- AND ischema.table_name = pgindex.tablename
- AND ischema.index_name = pgindex.indexname
- AND pgindex.crdb_oid = $1
- AND ischema.seq_in_index = $2`, args[0], args[1])
- if err != nil {
- return nil, err
- }
- // If the column number does not exist in the index we return an empty string.
- if len(r) == 0 {
- return tree.NewDString(""), nil
- }
if len(r) > 1 {
return nil, errors.AssertionFailedf("pg_get_indexdef query has more than 1 result row: %+v", r)
}
return r[0], nil
},
- Info: notUsableInfo,
+ Info: "Gets the CREATE INDEX command for index, or definition of just one index column when given a column number",
Volatility: volatility.Stable,
}
}
From 22b8d19e18974a98c3c8f3d0a29e5a7bd9a3cece Mon Sep 17 00:00:00 2001
From: Rafi Shamim
Date: Tue, 17 Jan 2023 20:32:42 -0500
Subject: [PATCH 2/3] builtins: implement pg_get_indexdef as UDF
Release note: None
---
docs/generated/sql/functions.md | 4 ++
pkg/sql/sem/builtins/pg_builtins.go | 74 ++++++++++++-----------------
2 files changed, 34 insertions(+), 44 deletions(-)
diff --git a/docs/generated/sql/functions.md b/docs/generated/sql/functions.md
index 35786d7aed18..a626bc951097 100644
--- a/docs/generated/sql/functions.md
+++ b/docs/generated/sql/functions.md
@@ -3538,6 +3538,10 @@ table. Returns an error if validation fails.
pg_get_viewdef(view_oid: oid) → string | Returns the CREATE statement for an existing view.
diff --git a/pkg/sql/sem/builtins/pg_builtins.go b/pkg/sql/sem/builtins/pg_builtins.go
index 18f8cacfbb6a..7edb8a8fd117 100644
--- a/pkg/sql/sem/builtins/pg_builtins.go
+++ b/pkg/sql/sem/builtins/pg_builtins.go
@@ -204,48 +204,6 @@ var (
datEncodingUTF8ShortName = tree.NewDString("UTF8")
)
-// Make a pg_get_indexdef function with the given arguments.
-func makePGGetIndexDef(paramTypes tree.ParamTypes) tree.Overload {
- return tree.Overload{
- Types: paramTypes,
- ReturnType: tree.FixedReturnType(types.String),
- Fn: func(ctx context.Context, evalCtx *eval.Context, args tree.Datums) (tree.Datum, error) {
- colNumber := *tree.NewDInt(0)
- if len(args) == 3 {
- // The 1 argument and 3 argument variants are equivalent when column number 0 is passed.
- colNumber = *args[1].(*tree.DInt)
- }
- // The 3 argument variant for column number other than 0 returns the column name.
- r, err := evalCtx.Planner.QueryRowEx(
- ctx, "pg_get_indexdef",
- sessiondata.NoSessionDataOverride,
- `SELECT CASE
- WHEN $2 = 0 THEN defs.indexdef
- -- If the column number does not exist in the index we return an empty string.
- WHEN $2 < 0 OR $2 > array_length(i.indkey, 1) THEN ''
- WHEN i.indkey[$2-1] = 0 THEN (indexprs::STRING[])[array_position(array_positions(i.indkey, 0), $2)]
- ELSE a.attname
- END as pg_get_indexdef
- FROM pg_catalog.pg_index i
- LEFT JOIN pg_attribute a ON (a.attrelid = i.indexrelid AND a.attnum = $2)
- LEFT JOIN pg_indexes defs ON ($2 = 0 AND defs.crdb_oid = i.indexrelid)
- WHERE i.indexrelid = $1`, args[0], colNumber)
- if err != nil {
- return nil, err
- }
- if len(r) == 0 {
- return tree.DNull, nil
- }
- if len(r) > 1 {
- return nil, errors.AssertionFailedf("pg_get_indexdef query has more than 1 result row: %+v", r)
- }
- return r[0], nil
- },
- Info: "Gets the CREATE INDEX command for index, or definition of just one index column when given a column number",
- Volatility: volatility.Stable,
- }
-}
-
// Make a pg_get_viewdef function with the given arguments.
func makePGGetViewDef(paramTypes tree.ParamTypes) tree.Overload {
return tree.Overload{
@@ -708,8 +666,36 @@ var pgBuiltins = map[string]builtinDefinition{
// statement.
"pg_get_indexdef": makeBuiltin(
tree.FunctionProperties{Category: builtinconstants.CategorySystemInfo, DistsqlBlocklist: true},
- makePGGetIndexDef(tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}}),
- makePGGetIndexDef(tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}, {Name: "column_no", Typ: types.Int}, {Name: "pretty_bool", Typ: types.Bool}}),
+ tree.Overload{
+ IsUDF: true,
+ Types: tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}},
+ ReturnType: tree.FixedReturnType(types.String),
+ Body: `SELECT indexdef FROM pg_catalog.pg_indexes WHERE crdb_oid = $1`,
+ Info: "Gets the CREATE INDEX command for index",
+ Volatility: volatility.Stable,
+ },
+ tree.Overload{
+ IsUDF: true,
+ Types: tree.ParamTypes{{Name: "index_oid", Typ: types.Oid}, {Name: "column_no", Typ: types.Int}, {Name: "pretty_bool", Typ: types.Bool}},
+ ReturnType: tree.FixedReturnType(types.String),
+ Body: `SELECT CASE
+ WHEN $2 = 0 THEN defs.indexdef
+ WHEN $2 < 0 OR $2 > array_length(i.indkey, 1) THEN ''
+ -- array_positions(i.indkey, 0) returns the 1-based indexes of the indkey elements that are 0.
+ -- array_position(arr, $2) returns the 1-based index of the value $2 in arr.
+ -- indkey is an int2vector, which is accessed with 0-based indexes.
+ -- indexprs is a string[], which is accessed with 1-based indexes.
+ -- To put this all together, for the k-th 0 value inside of indkey, this will find the k-th indexpr.
+ WHEN i.indkey[$2-1] = 0 THEN (indexprs::STRING[])[array_position(array_positions(i.indkey, 0), $2)]
+ ELSE a.attname
+ END as pg_get_indexdef
+ FROM pg_catalog.pg_index i
+ LEFT JOIN pg_attribute a ON (a.attrelid = i.indexrelid AND a.attnum = $2)
+ LEFT JOIN pg_indexes defs ON ($2 = 0 AND defs.crdb_oid = i.indexrelid)
+ WHERE i.indexrelid = $1`,
+ Info: "Gets the CREATE INDEX command for index, or definition of just one index column when given a non-zero column number",
+ Volatility: volatility.Stable,
+ },
),
// pg_get_viewdef functions like SHOW CREATE VIEW but returns the same format as
From b80c3d7c743e970d291fab700e2d6a54909cdadd Mon Sep 17 00:00:00 2001
From: Rafi Shamim
Date: Wed, 18 Jan 2023 21:38:45 -0500
Subject: [PATCH 3/3] sql: add index expression to SHOW INDEXES
Release note (sql change): SHOW INDEXES will now show the expression
used to define an index, if one was used.
---
pkg/sql/delegate/show_database_indexes.go | 25 ++--
pkg/sql/delegate/show_table.go | 25 ++--
pkg/sql/descriptor_mutation_test.go | 10 +-
.../testdata/logic_test/alter_primary_key | 6 +-
.../logictest/testdata/logic_test/alter_table | 48 ++++----
.../testdata/logic_test/create_index | 64 +++++-----
.../testdata/logic_test/create_table | 4 +-
.../logictest/testdata/logic_test/drop_index | 112 +++++++++---------
pkg/sql/logictest/testdata/logic_test/fk | 64 +++++-----
.../testdata/logic_test/information_schema | 4 +-
.../testdata/logic_test/new_schema_changer | 96 +++++++--------
.../logictest/testdata/logic_test/pg_catalog | 4 +-
.../testdata/logic_test/rename_column | 20 ++--
.../testdata/logic_test/rename_index | 74 ++++++------
.../testdata/logic_test/show_indexes | 79 ++++++------
.../logictest/testdata/logic_test/show_source | 74 ++++++------
pkg/sql/logictest/testdata/logic_test/storing | 28 ++---
pkg/sql/logictest/testdata/logic_test/table | 82 ++++++-------
pkg/sql/opt/exec/execbuilder/testdata/explain | 34 +++++-
.../execbuilder/testdata/not_visible_index | 60 +++++-----
pkg/sql/opt/exec/execbuilder/testdata/select | 28 ++---
.../exec/execbuilder/testdata/select_index | 14 +--
pkg/sql/pgwire/pgwire_test.go | 12 +-
23 files changed, 507 insertions(+), 460 deletions(-)
diff --git a/pkg/sql/delegate/show_database_indexes.go b/pkg/sql/delegate/show_database_indexes.go
index 73f2c7ac5297..791693182a04 100644
--- a/pkg/sql/delegate/show_database_indexes.go
+++ b/pkg/sql/delegate/show_database_indexes.go
@@ -31,9 +31,19 @@ func (d *delegator) delegateShowDatabaseIndexes(
SELECT
table_name,
index_name,
+ index_schema,
non_unique::BOOL,
seq_in_index,
column_name,
+ CASE
+ -- array_positions(i.indkey, 0) returns the 1-based indexes of the indkey elements that are 0.
+ -- array_position(arr, seq_in_index) returns the 1-based index of the value seq_in_index in arr.
+ -- indkey is an int2vector, which is accessed with 0-based indexes.
+ -- indexprs is a string[], which is accessed with 1-based indexes.
+ -- To put this all together, for the k-th 0 value inside of indkey, this will find the k-th indexpr.
+ WHEN i.indkey[seq_in_index-1] = 0 THEN (indexprs::STRING[])[array_position(array_positions(i.indkey, 0), seq_in_index)]
+ ELSE column_name
+ END AS definition,
direction,
storing::BOOL,
implicit::BOOL,
@@ -41,18 +51,17 @@ SELECT
if n.WithComment {
getAllIndexesQuery += `,
- obj_description(pg_class.oid) AS comment`
+ obj_description(c.oid) AS comment`
}
getAllIndexesQuery += `
FROM
- %s.information_schema.statistics`
-
- if n.WithComment {
- getAllIndexesQuery += `
- LEFT JOIN pg_class ON
- statistics.index_name = pg_class.relname`
- }
+ %[1]s.information_schema.statistics AS s
+ JOIN %[1]s.pg_catalog.pg_class c ON c.relname = s.index_name
+ JOIN %[1]s.pg_catalog.pg_class c_table ON c_table.relname = s.table_name
+ JOIN %[1]s.pg_catalog.pg_namespace n ON c.relnamespace = n.oid AND c_table.relnamespace = n.oid AND n.nspname = s.index_schema
+ JOIN %[1]s.pg_catalog.pg_index i ON i.indexrelid = c.oid AND i.indrelid = c_table.oid
+`
getAllIndexesQuery += `
ORDER BY 1, 2, 4`
diff --git a/pkg/sql/delegate/show_table.go b/pkg/sql/delegate/show_table.go
index ef1ca2a92b41..4fda63857a15 100644
--- a/pkg/sql/delegate/show_table.go
+++ b/pkg/sql/delegate/show_table.go
@@ -137,6 +137,15 @@ SELECT
non_unique::BOOL,
seq_in_index,
column_name,
+ CASE
+ -- array_positions(i.indkey, 0) returns the 1-based indexes of the indkey elements that are 0.
+ -- array_position(arr, seq_in_index) returns the 1-based index of the value seq_in_index in arr.
+ -- indkey is an int2vector, which is accessed with 0-based indexes.
+ -- indexprs is a string[], which is accessed with 1-based indexes.
+ -- To put this all together, for the k-th 0 value inside of indkey, this will find the k-th indexpr.
+ WHEN i.indkey[seq_in_index-1] = 0 THEN (indexprs::STRING[])[array_position(array_positions(i.indkey, 0), seq_in_index)]
+ ELSE column_name
+ END AS definition,
direction,
storing::BOOL,
implicit::BOOL,
@@ -144,19 +153,17 @@ SELECT
if n.WithComment {
getIndexesQuery += `,
- obj_description(pg_indexes.crdb_oid) AS comment`
+ obj_description(c.oid) AS comment`
}
getIndexesQuery += `
FROM
- %[4]s.information_schema.statistics AS s`
-
- if n.WithComment {
- getIndexesQuery += `
- LEFT JOIN pg_indexes ON
- pg_indexes.tablename = s.table_name AND
- pg_indexes.indexname = s.index_name`
- }
+ %[4]s.information_schema.statistics AS s
+ JOIN %[4]s.pg_catalog.pg_class c ON c.relname = s.index_name
+ JOIN %[4]s.pg_catalog.pg_class c_table ON c_table.relname = s.table_name
+ JOIN %[4]s.pg_catalog.pg_namespace n ON c.relnamespace = n.oid AND c_table.relnamespace = n.oid AND n.nspname = s.index_schema
+ JOIN %[4]s.pg_catalog.pg_index i ON i.indexrelid = c.oid AND i.indrelid = c_table.oid
+`
getIndexesQuery += `
WHERE
diff --git a/pkg/sql/descriptor_mutation_test.go b/pkg/sql/descriptor_mutation_test.go
index 8e0a77ae421d..bfedffe6a7f3 100644
--- a/pkg/sql/descriptor_mutation_test.go
+++ b/pkg/sql/descriptor_mutation_test.go
@@ -1049,11 +1049,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", "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"},
+ {"test", "test_pkey", "false", "1", "a", "a", "ASC", "false", "false", "true"},
+ {"test", "test_pkey", "false", "2", "b", "b", "N/A", "true", "false", "true"},
+ {"test", "test_pkey", "false", "3", "d", "d", "N/A", "true", "false", "true"},
+ {"test", "ufo", "true", "1", "d", "d", "ASC", "false", "false", "true"},
+ {"test", "ufo", "true", "2", "a", "a", "ASC", "false", "true", "true"},
},
)
diff --git a/pkg/sql/logictest/testdata/logic_test/alter_primary_key b/pkg/sql/logictest/testdata/logic_test/alter_primary_key
index e41b527caa58..aa55f110b85a 100644
--- a/pkg/sql/logictest/testdata/logic_test/alter_primary_key
+++ b/pkg/sql/logictest/testdata/logic_test/alter_primary_key
@@ -1613,13 +1613,13 @@ CREATE TABLE t (a INT PRIMARY KEY, b INT NOT NULL, UNIQUE INDEX t_a_key (a));
statement ok
ALTER TABLE t ALTER PRIMARY KEY USING COLUMNS (b);
-query TTT
+query TTT rowsort
SELECT index_name, column_name, direction FROM [SHOW INDEXES FROM t]
----
t_pkey b ASC
-t_pkey a N/A
-t_a_key a ASC
t_a_key b ASC
+t_a_key a ASC
+t_pkey a N/A
# But if the existing index is not strictly equal to the (old) primary key
# (even if, for example, the (old) primary key is a strict prefix of an
diff --git a/pkg/sql/logictest/testdata/logic_test/alter_table b/pkg/sql/logictest/testdata/logic_test/alter_table
index 869ee95df23d..6d4d0350f2af 100644
--- a/pkg/sql/logictest/testdata/logic_test/alter_table
+++ b/pkg/sql/logictest/testdata/logic_test/alter_table
@@ -50,17 +50,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 TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t foo false 1 b b ASC false false true
+t foo false 2 a a ASC true true true
+t t_f_idx true 1 f f ASC false false true
+t t_f_idx true 2 a a ASC false true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 f f N/A true false true
+t t_pkey false 3 b b N/A true false true
query III
SELECT * FROM t
@@ -243,16 +243,16 @@ NEW SCHEMA CHANGE DROP INDEX test.public.t@foo CASCADE root succeeded
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t t_f_idx true 1 f f ASC false false true
+t t_f_idx true 2 a a ASC false true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 f f N/A true false true
+t t_pkey false 3 b b N/A true false true
+t t_pkey false 4 c c N/A true false true
statement ok
ALTER TABLE t DROP b, DROP c
@@ -414,15 +414,15 @@ ALTER TABLE t DROP COLUMN g CASCADE
statement ok
ALTER TABLE o DROP COLUMN h
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM o
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+o o_pkey false 1 rowid rowid ASC false false true
+o o_pkey false 2 gf gf N/A true false true
+o o_pkey false 3 i i N/A true false true
+o oi true 1 i i ASC false false true
+o oi true 2 rowid rowid ASC false true true
statement ok
ALTER TABLE t ADD f INT CHECK (f > 1)
diff --git a/pkg/sql/logictest/testdata/logic_test/create_index b/pkg/sql/logictest/testdata/logic_test/create_index
index a274bb8e8bbd..bca10b313251 100644
--- a/pkg/sql/logictest/testdata/logic_test/create_index
+++ b/pkg/sql/logictest/testdata/logic_test/create_index
@@ -25,14 +25,14 @@ CREATE INDEX bar ON t (c)
statement error index \"bar\" contains duplicate column \"b\"
CREATE INDEX bar ON t (b, b);
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t foo true 1 b b ASC false false true
+t foo true 2 a a ASC false true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 b b N/A true false true
statement ok
INSERT INTO t VALUES (2,1)
@@ -40,14 +40,14 @@ INSERT INTO t VALUES (2,1)
statement error pgcode 23505 violates unique constraint "bar"
CREATE UNIQUE INDEX bar ON t (b)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t foo true 1 b b ASC false false true
+t foo true 2 a a ASC false true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 b b N/A true false true
# test for DESC index
@@ -70,18 +70,18 @@ CREATE INDEX b_desc ON t (b DESC)
statement ok
CREATE INDEX b_asc ON t (b ASC, c DESC)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t b_asc true 1 b b ASC false false true
+t b_asc true 2 c c DESC false false true
+t b_asc true 3 a a ASC false true true
+t b_desc true 1 b b DESC false false true
+t b_desc true 2 a a ASC false true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 b b N/A true false true
+t t_pkey false 3 c c N/A true false true
statement error pgcode 42P01 relation "foo" does not exist
CREATE INDEX fail ON foo (b DESC)
@@ -110,12 +110,12 @@ CREATE INDEX foo ON privs (b)
user root
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM privs
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+privs privs_pkey false 1 a a ASC false false true
+privs privs_pkey false 2 b b N/A true false true
statement ok
GRANT CREATE ON privs TO testuser
@@ -125,14 +125,14 @@ user testuser
statement ok
CREATE INDEX foo ON privs (b)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM privs
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+privs foo true 1 b b ASC false false true
+privs foo true 2 a a ASC false true true
+privs privs_pkey false 1 a a ASC false false true
+privs privs_pkey false 2 b b N/A true false true
user root
diff --git a/pkg/sql/logictest/testdata/logic_test/create_table b/pkg/sql/logictest/testdata/logic_test/create_table
index b60baf51abb2..6a542c1d07a4 100644
--- a/pkg/sql/logictest/testdata/logic_test/create_table
+++ b/pkg/sql/logictest/testdata/logic_test/create_table
@@ -57,12 +57,12 @@ rowid
rowid_1
rowid_2
-query TT
+query TT rowsort
SELECT index_name, column_name FROM [SHOW INDEXES FROM t]
----
t_pkey rowid_2
-t_pkey rowid
t_pkey rowid_1
+t_pkey rowid
query TT
SHOW CREATE t
diff --git a/pkg/sql/logictest/testdata/logic_test/drop_index b/pkg/sql/logictest/testdata/logic_test/drop_index
index 13a1a2697fe8..e5878b7aec6b 100644
--- a/pkg/sql/logictest/testdata/logic_test/drop_index
+++ b/pkg/sql/logictest/testdata/logic_test/drop_index
@@ -54,17 +54,17 @@ DROP INDEX baw
statement ok
INSERT INTO users VALUES (1, 'tom', 'cat'),(2, 'jerry', 'rat')
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
statement error index "zap" does not exist
DROP INDEX users@zap
@@ -72,32 +72,32 @@ DROP INDEX users@zap
statement ok
DROP INDEX IF EXISTS users@zap
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
# Also test that dropping with a non-existing index still drops 'foo'.
statement ok
DROP INDEX IF EXISTS users@foo, users@zap
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
user testuser
@@ -126,13 +126,13 @@ DROP INDEX users@bar RESTRICT
statement ok
DROP INDEX users@bar CASCADE
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
user root
@@ -154,17 +154,17 @@ CREATE INDEX baz ON users (name, title)
statement ok
DROP INDEX IF EXISTS users@invalid, users@baz
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar true 1 title ASC false false true
-users bar true 2 id ASC false true true
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar true 1 title title ASC false false true
+users bar true 2 id id ASC false true true
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
statement ok
CREATE VIEW v AS SELECT name FROM users@{FORCE_INDEX=foo}
@@ -175,15 +175,15 @@ DROP INDEX users@foo
statement ok
DROP INDEX users@bar
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
statement ok
CREATE VIEW v2 AS SELECT name FROM v
@@ -211,13 +211,13 @@ user root
statement ok
DROP INDEX users@foo CASCADE
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
query TTTTIT
SHOW TABLES
@@ -251,13 +251,13 @@ CREATE INDEX baz ON users (name)
statement ok
DROP INDEX IF EXISTS baz, zap
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
# Test that it still succeeds when an index does not exist.
diff --git a/pkg/sql/logictest/testdata/logic_test/fk b/pkg/sql/logictest/testdata/logic_test/fk
index 93dfa5dd1780..4e31c83ed372 100644
--- a/pkg/sql/logictest/testdata/logic_test/fk
+++ b/pkg/sql/logictest/testdata/logic_test/fk
@@ -295,12 +295,12 @@ CREATE TABLE missing_col (customer INT REFERENCES customers (idz))
statement ok
CREATE TABLE unindexed (customer INT REFERENCES customers)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM unindexed
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-unindexed unindexed_pkey false 1 rowid ASC false false true
-unindexed unindexed_pkey false 2 customer N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+unindexed unindexed_pkey false 1 rowid rowid ASC false false true
+unindexed unindexed_pkey false 2 customer customer N/A true false true
statement error there is no unique constraint matching given keys for referenced table products
CREATE TABLE non_unique (product STRING REFERENCES products (vendor))
@@ -783,32 +783,32 @@ CREATE TABLE refpairs_wrong_order (
INDEX (b, a)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM refpairs_wrong_order
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-refpairs_wrong_order refpairs_wrong_order_b_a_idx true 1 b ASC false false true
-refpairs_wrong_order refpairs_wrong_order_b_a_idx true 2 a ASC false false true
-refpairs_wrong_order refpairs_wrong_order_b_a_idx true 3 rowid ASC false true true
-refpairs_wrong_order refpairs_wrong_order_pkey false 1 rowid ASC false false true
-refpairs_wrong_order refpairs_wrong_order_pkey false 2 a N/A true false true
-refpairs_wrong_order refpairs_wrong_order_pkey false 3 b N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+refpairs_wrong_order refpairs_wrong_order_b_a_idx true 1 b b ASC false false true
+refpairs_wrong_order refpairs_wrong_order_b_a_idx true 2 a a ASC false false true
+refpairs_wrong_order refpairs_wrong_order_b_a_idx true 3 rowid rowid ASC false true true
+refpairs_wrong_order refpairs_wrong_order_pkey false 1 rowid rowid ASC false false true
+refpairs_wrong_order refpairs_wrong_order_pkey false 2 a a N/A true false true
+refpairs_wrong_order refpairs_wrong_order_pkey false 3 b b N/A true false true
statement ok
CREATE TABLE refpairs_c_between (a INT, b STRING, c INT, FOREIGN KEY (a, b) REFERENCES pairs (src, dest), INDEX (a, c, b))
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM refpairs_c_between
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-refpairs_c_between refpairs_c_between_a_c_b_idx true 1 a ASC false false true
-refpairs_c_between refpairs_c_between_a_c_b_idx true 2 c ASC false false true
-refpairs_c_between refpairs_c_between_a_c_b_idx true 3 b ASC false false true
-refpairs_c_between refpairs_c_between_a_c_b_idx true 4 rowid ASC false true true
-refpairs_c_between refpairs_c_between_pkey false 1 rowid ASC false false true
-refpairs_c_between refpairs_c_between_pkey false 2 a N/A true false true
-refpairs_c_between refpairs_c_between_pkey false 3 b N/A true false true
-refpairs_c_between refpairs_c_between_pkey false 4 c N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+refpairs_c_between refpairs_c_between_a_c_b_idx true 1 a a ASC false false true
+refpairs_c_between refpairs_c_between_a_c_b_idx true 2 c c ASC false false true
+refpairs_c_between refpairs_c_between_a_c_b_idx true 3 b b ASC false false true
+refpairs_c_between refpairs_c_between_a_c_b_idx true 4 rowid rowid ASC false true true
+refpairs_c_between refpairs_c_between_pkey false 1 rowid rowid ASC false false true
+refpairs_c_between refpairs_c_between_pkey false 2 a a N/A true false true
+refpairs_c_between refpairs_c_between_pkey false 3 b b N/A true false true
+refpairs_c_between refpairs_c_between_pkey false 4 c c N/A true false true
statement ok
CREATE TABLE refpairs (
@@ -820,18 +820,18 @@ CREATE TABLE refpairs (
FAMILY "primary" (a, b, c, rowid)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM refpairs
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-refpairs refpairs_a_b_c_idx true 1 a ASC false false true
-refpairs refpairs_a_b_c_idx true 2 b ASC false false true
-refpairs refpairs_a_b_c_idx true 3 c ASC false false true
-refpairs refpairs_a_b_c_idx true 4 rowid ASC false true true
-refpairs refpairs_pkey false 1 rowid ASC false false true
-refpairs refpairs_pkey false 2 a N/A true false true
-refpairs refpairs_pkey false 3 b N/A true false true
-refpairs refpairs_pkey false 4 c N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+refpairs refpairs_a_b_c_idx true 1 a a ASC false false true
+refpairs refpairs_a_b_c_idx true 2 b b ASC false false true
+refpairs refpairs_a_b_c_idx true 3 c c ASC false false true
+refpairs refpairs_a_b_c_idx true 4 rowid rowid ASC false true true
+refpairs refpairs_pkey false 1 rowid rowid ASC false false true
+refpairs refpairs_pkey false 2 a a N/A true false true
+refpairs refpairs_pkey false 3 b b N/A true false true
+refpairs refpairs_pkey false 4 c c N/A true false true
query TT
SHOW CREATE TABLE refpairs
diff --git a/pkg/sql/logictest/testdata/logic_test/information_schema b/pkg/sql/logictest/testdata/logic_test/information_schema
index 95a752d75e64..71bf232876fa 100644
--- a/pkg/sql/logictest/testdata/logic_test/information_schema
+++ b/pkg/sql/logictest/testdata/logic_test/information_schema
@@ -344,10 +344,10 @@ table_type STRING false NULL ·
is_insertable_into STRING false NULL · {} false
version INT8 true NULL · {} false
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM information_schema.tables
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
query TTTTB colnames
SHOW CONSTRAINTS FROM information_schema.tables
diff --git a/pkg/sql/logictest/testdata/logic_test/new_schema_changer b/pkg/sql/logictest/testdata/logic_test/new_schema_changer
index 6b363816d2ca..54341343cd9b 100644
--- a/pkg/sql/logictest/testdata/logic_test/new_schema_changer
+++ b/pkg/sql/logictest/testdata/logic_test/new_schema_changer
@@ -871,22 +871,22 @@ CREATE TABLE tIndx2 (a INT PRIMARY KEY, b INT, INDEX ((a+b)))
statement ok
CREATE TABLE tIndx3 (a INT PRIMARY KEY, b INT, INVERTED INDEX ((ARRAY[a,b])))
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM tIndex
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-tindex bar true 1 crdb_internal_idx_expr ASC false false true
-tindex bar true 2 a ASC false true true
-tindex bar2 true 1 crdb_internal_idx_expr_1 ASC false false true
-tindex bar2 true 2 a ASC false true true
-tindex bar3 false 1 crdb_internal_idx_expr_1 ASC false false true
-tindex bar3 false 2 a ASC true true true
-tindex bar4 true 1 crdb_internal_idx_expr_2 ASC false false true
-tindex bar4 true 2 a ASC false true true
-tindex foo true 1 b ASC false false true
-tindex foo true 2 a ASC false true true
-tindex tindex_pkey false 1 a ASC false false true
-tindex tindex_pkey false 2 b N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+tindex bar true 1 crdb_internal_idx_expr (a + b) ASC false false true
+tindex bar true 2 a a ASC false true true
+tindex bar2 true 1 crdb_internal_idx_expr_1 (abs(b)) ASC false false true
+tindex bar2 true 2 a a ASC false true true
+tindex bar3 false 1 crdb_internal_idx_expr_1 (abs(b)) ASC false false true
+tindex bar3 false 2 a a ASC true true true
+tindex bar4 true 1 crdb_internal_idx_expr_2 (ARRAY[a, b]) ASC false false true
+tindex bar4 true 2 a a ASC false true true
+tindex foo true 1 b b ASC false false true
+tindex foo true 2 a a ASC false true true
+tindex tindex_pkey false 1 a a ASC false false true
+tindex tindex_pkey false 2 b b N/A true false true
statement error duplicate key value violates unique constraint "bar3"
INSERT INTO tIndex VALUES (2,1)
@@ -898,22 +898,22 @@ INSERT INTO tIndex VALUES (20000,10000)
#statement error pgcode 23505 violates unique constraint "bar"
#CREATE UNIQUE INDEX bar ON tIndex (b)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM tIndex
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-tindex bar true 1 crdb_internal_idx_expr ASC false false true
-tindex bar true 2 a ASC false true true
-tindex bar2 true 1 crdb_internal_idx_expr_1 ASC false false true
-tindex bar2 true 2 a ASC false true true
-tindex bar3 false 1 crdb_internal_idx_expr_1 ASC false false true
-tindex bar3 false 2 a ASC true true true
-tindex bar4 true 1 crdb_internal_idx_expr_2 ASC false false true
-tindex bar4 true 2 a ASC false true true
-tindex foo true 1 b ASC false false true
-tindex foo true 2 a ASC false true true
-tindex tindex_pkey false 1 a ASC false false true
-tindex tindex_pkey false 2 b N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+tindex bar true 1 crdb_internal_idx_expr (a + b) ASC false false true
+tindex bar true 2 a a ASC false true true
+tindex bar2 true 1 crdb_internal_idx_expr_1 (abs(b)) ASC false false true
+tindex bar2 true 2 a a ASC false true true
+tindex bar3 false 1 crdb_internal_idx_expr_1 (abs(b)) ASC false false true
+tindex bar3 false 2 a a ASC true true true
+tindex bar4 true 1 crdb_internal_idx_expr_2 (ARRAY[a, b]) ASC false false true
+tindex bar4 true 2 a a ASC false true true
+tindex foo true 1 b b ASC false false true
+tindex foo true 2 a a ASC false true true
+tindex tindex_pkey false 1 a a ASC false false true
+tindex tindex_pkey false 2 b b N/A true false true
# test for DESC index
@@ -936,18 +936,18 @@ CREATE INDEX b_desc ON tIndx (b DESC)
statement ok
CREATE INDEX b_asc ON tIndx (b ASC, c DESC)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM tIndx
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-tindx b_asc true 1 b ASC false false true
-tindx b_asc true 2 c DESC false false true
-tindx b_asc true 3 a ASC false true true
-tindx b_desc true 1 b DESC false false true
-tindx b_desc true 2 a ASC false true true
-tindx tindx_pkey false 1 a ASC false false true
-tindx tindx_pkey false 2 b N/A true false true
-tindx tindx_pkey false 3 c N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+tindx b_asc true 1 b b ASC false false true
+tindx b_asc true 2 c c DESC false false true
+tindx b_asc true 3 a a ASC false true true
+tindx b_desc true 1 b b DESC false false true
+tindx b_desc true 2 a a ASC false true true
+tindx tindx_pkey false 1 a a ASC false false true
+tindx tindx_pkey false 2 b b N/A true false true
+tindx tindx_pkey false 3 c c N/A true false true
statement error pgcode 42P01 relation "foo" does not exist
CREATE INDEX fail ON foo (b DESC)
@@ -973,12 +973,12 @@ CREATE INDEX foo ON privs (b)
user root
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM privs
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+privs privs_pkey false 1 a a ASC false false true
+privs privs_pkey false 2 b b N/A true false true
statement ok
GRANT CREATE ON privs TO testuser
@@ -988,14 +988,14 @@ user testuser
statement ok
CREATE INDEX foo ON privs (b)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM privs
----
-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
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+privs foo true 1 b b ASC false false true
+privs foo true 2 a a ASC false true true
+privs privs_pkey false 1 a a ASC false false true
+privs privs_pkey false 2 b b N/A true false true
user root
diff --git a/pkg/sql/logictest/testdata/logic_test/pg_catalog b/pkg/sql/logictest/testdata/logic_test/pg_catalog
index a0544fcb7999..3b84f249c1f4 100644
--- a/pkg/sql/logictest/testdata/logic_test/pg_catalog
+++ b/pkg/sql/logictest/testdata/logic_test/pg_catalog
@@ -325,10 +325,10 @@ nspname NAME false NULL · {}
nspowner OID true NULL · {} false
nspacl STRING[] true NULL · {} false
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM pg_catalog.pg_namespace
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
query TTTTB colnames
SHOW CONSTRAINTS FROM pg_catalog.pg_namespace
diff --git a/pkg/sql/logictest/testdata/logic_test/rename_column b/pkg/sql/logictest/testdata/logic_test/rename_column
index 775039015c25..34d7e32f405a 100644
--- a/pkg/sql/logictest/testdata/logic_test/rename_column
+++ b/pkg/sql/logictest/testdata/logic_test/rename_column
@@ -70,18 +70,18 @@ id username species
2 jerry rat
# Renaming a column updates the column names in an index.
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 username ASC false false true
-users foo true 1 username ASC false false true
-users foo true 2 species N/A true false true
-users foo true 3 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 username N/A true false true
-users users_pkey false 3 species N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 username username ASC false false true
+users foo true 1 username username ASC false false true
+users foo true 2 species species N/A true false true
+users foo true 3 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 username username N/A true false true
+users users_pkey false 3 species species N/A true false true
statement ok
CREATE VIEW v1 AS SELECT id FROM users WHERE username = 'tom'
diff --git a/pkg/sql/logictest/testdata/logic_test/rename_index b/pkg/sql/logictest/testdata/logic_test/rename_index
index 1a71e8b18947..e249903d8106 100644
--- a/pkg/sql/logictest/testdata/logic_test/rename_index
+++ b/pkg/sql/logictest/testdata/logic_test/rename_index
@@ -22,29 +22,29 @@ INSERT INTO users VALUES (1, 'tom', 'cat'),(2, 'jerry', 'rat')
statement ok
INSERT INTO users_dupe VALUES (1, 'tom', 'cat'),(2, 'jerry', 'rat')
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
-
-query TTBITTBBB colnames
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
+
+query TTBITTTBBB colnames
SHOW INDEXES FROM users_dupe
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users_dupe bar false 1 id ASC false false true
-users_dupe bar false 2 name ASC false false true
-users_dupe foo true 1 name ASC false false true
-users_dupe foo true 2 id ASC false true true
-users_dupe users_dupe_pkey false 1 id ASC false false true
-users_dupe users_dupe_pkey false 2 name N/A true false true
-users_dupe users_dupe_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users_dupe bar false 1 id id ASC false false true
+users_dupe bar false 2 name name ASC false false true
+users_dupe foo true 1 name name ASC false false true
+users_dupe foo true 2 id id ASC false true true
+users_dupe users_dupe_pkey false 1 id id ASC false false true
+users_dupe users_dupe_pkey false 2 name name N/A true false true
+users_dupe users_dupe_pkey false 3 title title N/A true false true
statement error pgcode 42P07 index name "bar" already exists
ALTER INDEX users@foo RENAME TO bar
@@ -80,17 +80,17 @@ ALTER INDEX IF EXISTS ufooo RENAME TO ufoo
statement ok
ALTER INDEX ufoo RENAME TO ufo
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users ufo true 1 name ASC false false true
-users ufo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users ufo true 1 name name ASC false false true
+users ufo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
user testuser
@@ -107,17 +107,17 @@ user testuser
statement ok
ALTER INDEX users@bar RENAME TO rar
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users rar false 1 id ASC false false true
-users rar false 2 name ASC false false true
-users ufo true 1 name ASC false false true
-users ufo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users rar false 1 id id ASC false false true
+users rar false 2 name name ASC false false true
+users ufo true 1 name name ASC false false true
+users ufo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
user root
diff --git a/pkg/sql/logictest/testdata/logic_test/show_indexes b/pkg/sql/logictest/testdata/logic_test/show_indexes
index 47b492b4a51c..75bec0f14110 100644
--- a/pkg/sql/logictest/testdata/logic_test/show_indexes
+++ b/pkg/sql/logictest/testdata/logic_test/show_indexes
@@ -6,23 +6,28 @@ CREATE TABLE t1 (
d INT,
PRIMARY KEY (a, b),
INDEX c_idx (c ASC),
- UNIQUE INDEX d_b_idx (d ASC, b ASC)
+ UNIQUE INDEX d_b_idx (d ASC, b ASC),
+ INDEX expr_idx ((a+b), c)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES from t1
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t1 c_idx true 1 c ASC false false true
-t1 c_idx true 2 a ASC false true true
-t1 c_idx true 3 b ASC false true true
-t1 d_b_idx false 1 d ASC false false true
-t1 d_b_idx false 2 b ASC false false true
-t1 d_b_idx false 3 a ASC true true true
-t1 t1_pkey false 1 a ASC false false true
-t1 t1_pkey false 2 b ASC false false true
-t1 t1_pkey false 3 c N/A true false true
-t1 t1_pkey false 4 d N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t1 c_idx true 1 c c ASC false false true
+t1 c_idx true 2 a a ASC false true true
+t1 c_idx true 3 b b ASC false true true
+t1 d_b_idx false 1 d d ASC false false true
+t1 d_b_idx false 2 b b ASC false false true
+t1 d_b_idx false 3 a a ASC true true true
+t1 expr_idx true 1 crdb_internal_idx_expr (a + b) ASC false false true
+t1 expr_idx true 2 c c ASC false false true
+t1 expr_idx true 3 a a ASC false true true
+t1 expr_idx true 4 b b ASC false true true
+t1 t1_pkey false 1 a a ASC false false true
+t1 t1_pkey false 2 b b ASC false false true
+t1 t1_pkey false 3 c c N/A true false true
+t1 t1_pkey false 4 d d N/A true false true
statement ok
CREATE TABLE t2 (
@@ -38,29 +43,29 @@ CREATE TABLE t2 (
INDEX d_idx (d ASC)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES from t2
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t2 a_e_c_idx true 1 a ASC false false true
-t2 a_e_c_idx true 2 e ASC false false true
-t2 a_e_c_idx true 3 c ASC false false true
-t2 a_e_c_idx true 4 b ASC false true true
-t2 b_d_idx false 1 b ASC false false true
-t2 b_d_idx false 2 d ASC false false true
-t2 b_d_idx false 3 c ASC true true true
-t2 b_d_idx false 4 a ASC true true true
-t2 c_e_d_a_idx false 1 c ASC false false true
-t2 c_e_d_a_idx false 2 e ASC false false true
-t2 c_e_d_a_idx false 3 d ASC false false true
-t2 c_e_d_a_idx false 4 a ASC false false true
-t2 c_e_d_a_idx false 5 b ASC true true true
-t2 d_idx true 1 d ASC false false true
-t2 d_idx true 2 c ASC false true true
-t2 d_idx true 3 b ASC false true true
-t2 d_idx true 4 a ASC false true true
-t2 t2_pkey false 1 c ASC false false true
-t2 t2_pkey false 2 b ASC false false true
-t2 t2_pkey false 3 a ASC false false true
-t2 t2_pkey false 4 d N/A true false true
-t2 t2_pkey false 5 e N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t2 a_e_c_idx true 1 a a ASC false false true
+t2 a_e_c_idx true 2 e e ASC false false true
+t2 a_e_c_idx true 3 c c ASC false false true
+t2 a_e_c_idx true 4 b b ASC false true true
+t2 b_d_idx false 1 b b ASC false false true
+t2 b_d_idx false 2 d d ASC false false true
+t2 b_d_idx false 3 c c ASC true true true
+t2 b_d_idx false 4 a a ASC true true true
+t2 c_e_d_a_idx false 1 c c ASC false false true
+t2 c_e_d_a_idx false 2 e e ASC false false true
+t2 c_e_d_a_idx false 3 d d ASC false false true
+t2 c_e_d_a_idx false 4 a a ASC false false true
+t2 c_e_d_a_idx false 5 b b ASC true true true
+t2 d_idx true 1 d d ASC false false true
+t2 d_idx true 2 c c ASC false true true
+t2 d_idx true 3 b b ASC false true true
+t2 d_idx true 4 a a ASC false true true
+t2 t2_pkey false 1 c c ASC false false true
+t2 t2_pkey false 2 b b ASC false false true
+t2 t2_pkey false 3 a a ASC false false true
+t2 t2_pkey false 4 d d N/A true false true
+t2 t2_pkey false 5 e e N/A true false true
diff --git a/pkg/sql/logictest/testdata/logic_test/show_source b/pkg/sql/logictest/testdata/logic_test/show_source
index c1a94857003e..63540b755311 100644
--- a/pkg/sql/logictest/testdata/logic_test/show_source
+++ b/pkg/sql/logictest/testdata/logic_test/show_source
@@ -221,12 +221,12 @@ database_name schema_name table_name grantee privilege_type is_grantable
system public descriptor admin SELECT true
system public descriptor root SELECT true
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW INDEX FROM system.descriptor]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-descriptor primary false 1 id ASC false false true
-descriptor primary false 2 descriptor N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+descriptor primary false 1 id id ASC false false true
+descriptor primary false 2 descriptor descriptor N/A true false true
query TTTTB colnames
SELECT * FROM [SHOW CONSTRAINT FROM system.descriptor]
@@ -234,12 +234,12 @@ SELECT * FROM [SHOW CONSTRAINT FROM system.descriptor]
table_name constraint_name constraint_type details validated
descriptor primary PRIMARY KEY PRIMARY KEY (id ASC) true
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW KEYS FROM system.descriptor]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-descriptor primary false 1 id ASC false false true
-descriptor primary false 2 descriptor N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+descriptor primary false 1 id id ASC false false true
+descriptor primary false 2 descriptor descriptor N/A true false true
query TT colnames,rowsort
SELECT * FROM [SHOW SCHEMAS FROM system]
@@ -526,11 +526,11 @@ CREATE TABLE showdbindexestest.table1 (key1 INT PRIMARY KEY);
statement ok
CREATE TABLE showdbindexestest.table2 (key2 INT PRIMARY KEY);
-query TTBITTBBB
+query TTTBITTTBBB
SHOW INDEXES FROM DATABASE showdbindexestest;
----
-table1 table1_pkey false 1 key1 ASC false false true
-table2 table2_pkey false 1 key2 ASC false false true
+table1 table1_pkey public false 1 key1 key1 ASC false false true
+table2 table2_pkey public false 1 key2 key2 ASC false false true
statement ok
CREATE DATABASE "$peci@l";
@@ -541,11 +541,11 @@ CREATE TABLE "$peci@l".table1 (key1 INT PRIMARY KEY);
statement ok
CREATE TABLE "$peci@l".table2 (key2 INT PRIMARY KEY);
-query TTBITTBBB
+query TTTBITTTBBB
SHOW INDEXES FROM DATABASE "$peci@l";
----
-table1 table1_pkey false 1 key1 ASC false false true
-table2 table2_pkey false 1 key2 ASC false false true
+table1 table1_pkey public false 1 key1 key1 ASC false false true
+table2 table2_pkey public false 1 key2 key2 ASC false false true
# Test SHOW LOCALITY telemetry.
query T
@@ -617,30 +617,30 @@ CREATE TABLE t (
COMMENT ON COLUMN t.z IS 'comm"en"t2';
COMMENT ON INDEX t@i2 IS 'comm''ent3'
-query TTBITTBBBT
+query TTBITTTBBBT
SHOW INDEXES FROM t WITH COMMENT
----
-t i1 true 1 x ASC false false true NULL
-t i1 true 2 rowid ASC false true true NULL
-t i2 true 1 y ASC false false true comm'ent3
-t i2 true 2 rowid ASC false true true comm'ent3
-t i3 true 1 z ASC false false true NULL
-t i3 true 2 rowid ASC false true true NULL
-t t_pkey false 1 rowid ASC false false true NULL
-t t_pkey false 2 x N/A true false true NULL
-t t_pkey false 3 y N/A true false true NULL
-t t_pkey false 4 z N/A true false true NULL
-
-query TTBITTBBBT
+t i1 true 1 x x ASC false false true NULL
+t i1 true 2 rowid rowid ASC false true true NULL
+t i2 true 1 y y ASC false false true comm'ent3
+t i2 true 2 rowid rowid ASC false true true comm'ent3
+t i3 true 1 z z ASC false false true NULL
+t i3 true 2 rowid rowid ASC false true true NULL
+t t_pkey false 1 rowid rowid ASC false false true NULL
+t t_pkey false 2 x x N/A true false true NULL
+t t_pkey false 3 y y N/A true false true NULL
+t t_pkey false 4 z z N/A true false true NULL
+
+query TTBITTTBBBT
SHOW INDEXES FROM t2 WITH COMMENT
----
-t2 i1 true 1 x ASC false false true NULL
-t2 i1 true 2 rowid ASC false true true NULL
-t2 i2 true 1 y ASC false false true NULL
-t2 i2 true 2 rowid ASC false true true NULL
-t2 i3 true 1 z ASC false false true NULL
-t2 i3 true 2 rowid ASC false true true NULL
-t2 t2_pkey false 1 rowid ASC false false true NULL
-t2 t2_pkey false 2 x N/A true false true NULL
-t2 t2_pkey false 3 y N/A true false true NULL
-t2 t2_pkey false 4 z N/A true false true NULL
+t2 i1 true 1 x x ASC false false true NULL
+t2 i1 true 2 rowid rowid ASC false true true NULL
+t2 i2 true 1 y y ASC false false true NULL
+t2 i2 true 2 rowid rowid ASC false true true NULL
+t2 i3 true 1 z z ASC false false true NULL
+t2 i3 true 2 rowid rowid ASC false true true NULL
+t2 t2_pkey false 1 rowid rowid ASC false false true NULL
+t2 t2_pkey false 2 x x N/A true false true NULL
+t2 t2_pkey false 3 y y N/A true false true NULL
+t2 t2_pkey false 4 z z N/A true false true NULL
diff --git a/pkg/sql/logictest/testdata/logic_test/storing b/pkg/sql/logictest/testdata/logic_test/storing
index bb5272703d8a..3354b1a523d2 100644
--- a/pkg/sql/logictest/testdata/logic_test/storing
+++ b/pkg/sql/logictest/testdata/logic_test/storing
@@ -8,22 +8,22 @@ CREATE TABLE t (
UNIQUE INDEX c_idx (c) STORING (b, d)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t b_idx true 1 b ASC false false true
-t b_idx true 2 c N/A true false true
-t b_idx true 3 d N/A true false true
-t b_idx true 4 a ASC false true true
-t c_idx false 1 c ASC false false true
-t c_idx false 2 b N/A true false true
-t c_idx false 3 d N/A true false true
-t c_idx false 4 a ASC true 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
-t t_pkey false 4 d N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t b_idx true 1 b b ASC false false true
+t b_idx true 2 c c N/A true false true
+t b_idx true 3 d d N/A true false true
+t b_idx true 4 a a ASC false true true
+t c_idx false 1 c c ASC false false true
+t c_idx false 2 b b N/A true false true
+t c_idx false 3 d d N/A true false true
+t c_idx false 4 a a ASC true true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 b b N/A true false true
+t t_pkey false 3 c c N/A true false true
+t t_pkey false 4 d d N/A true false true
statement ok
INSERT INTO t VALUES (1, 2, 3, 4)
diff --git a/pkg/sql/logictest/testdata/logic_test/table b/pkg/sql/logictest/testdata/logic_test/table
index 4bda6ac68612..26ff31543696 100644
--- a/pkg/sql/logictest/testdata/logic_test/table
+++ b/pkg/sql/logictest/testdata/logic_test/table
@@ -63,39 +63,39 @@ CREATE TABLE c (
statement ok
COMMENT ON INDEX c_foo_idx IS 'index_comment'
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM c
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-c c_bar_key false 1 bar ASC false false true
-c c_bar_key false 2 id ASC true true true
-c c_foo_bar_idx true 1 foo ASC false false true
-c c_foo_bar_idx true 2 bar DESC false false true
-c c_foo_bar_idx true 3 id ASC false true true
-c c_foo_idx true 1 foo ASC false false true
-c c_foo_idx true 2 id ASC false true true
-c c_foo_idx1 true 1 foo ASC false false true
-c c_foo_idx1 true 2 id ASC false true true
-c c_pkey false 1 id ASC false false true
-c c_pkey false 2 foo N/A true false true
-c c_pkey false 3 bar N/A true false true
-
-query TTBITTBBBT colnames
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+c c_bar_key false 1 bar bar ASC false false true
+c c_bar_key false 2 id id ASC true true true
+c c_foo_bar_idx true 1 foo foo ASC false false true
+c c_foo_bar_idx true 2 bar bar DESC false false true
+c c_foo_bar_idx true 3 id id ASC false true true
+c c_foo_idx true 1 foo foo ASC false false true
+c c_foo_idx true 2 id id ASC false true true
+c c_foo_idx1 true 1 foo foo ASC false false true
+c c_foo_idx1 true 2 id id ASC false true true
+c c_pkey false 1 id id ASC false false true
+c c_pkey false 2 foo foo N/A true false true
+c c_pkey false 3 bar bar N/A true false true
+
+query TTBITTTBBBT colnames
SHOW INDEXES FROM c WITH COMMENT
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible comment
-c c_bar_key false 1 bar ASC false false true NULL
-c c_bar_key false 2 id ASC true true true NULL
-c c_foo_bar_idx true 1 foo ASC false false true NULL
-c c_foo_bar_idx true 2 bar DESC false false true NULL
-c c_foo_bar_idx true 3 id ASC false true true NULL
-c c_foo_idx true 1 foo ASC false false true index_comment
-c c_foo_idx true 2 id ASC false true true index_comment
-c c_foo_idx1 true 1 foo ASC false false true NULL
-c c_foo_idx1 true 2 id ASC false true true NULL
-c c_pkey false 1 id ASC false false true NULL
-c c_pkey false 2 foo N/A true false true NULL
-c c_pkey false 3 bar N/A true false true NULL
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible comment
+c c_bar_key false 1 bar bar ASC false false true NULL
+c c_bar_key false 2 id id ASC true true true NULL
+c c_foo_bar_idx true 1 foo foo ASC false false true NULL
+c c_foo_bar_idx true 2 bar bar DESC false false true NULL
+c c_foo_bar_idx true 3 id id ASC false true true NULL
+c c_foo_idx true 1 foo foo ASC false false true index_comment
+c c_foo_idx true 2 id id ASC false true true index_comment
+c c_foo_idx1 true 1 foo foo ASC false false true NULL
+c c_foo_idx1 true 2 id id ASC false true true NULL
+c c_pkey false 1 id id ASC false false true NULL
+c c_pkey false 2 foo foo N/A true false true NULL
+c c_pkey false 3 bar bar N/A true false true NULL
# primary keys can never be null
@@ -199,20 +199,20 @@ nickname STRING true NULL ·
username STRING(10) true NULL · {users_pkey} false
email VARCHAR(100) true NULL · {users_pkey} false
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM test.users
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-users bar false 1 id ASC false false true
-users bar false 2 name ASC false false true
-users foo true 1 name ASC false false true
-users foo true 2 id ASC false true true
-users users_pkey false 1 id ASC false false true
-users users_pkey false 2 name N/A true false true
-users users_pkey false 3 title N/A true false true
-users users_pkey false 4 nickname N/A true false true
-users users_pkey false 5 username N/A true false true
-users users_pkey false 6 email N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+users bar false 1 id id ASC false false true
+users bar false 2 name name ASC false false true
+users foo true 1 name name ASC false false true
+users foo true 2 id id ASC false true true
+users users_pkey false 1 id id ASC false false true
+users users_pkey false 2 name name N/A true false true
+users users_pkey false 3 title title N/A true false true
+users users_pkey false 4 nickname nickname N/A true false true
+users users_pkey false 5 username username N/A true false true
+users users_pkey false 6 email email N/A true false true
statement error precision for type float must be at least 1 bit
CREATE TABLE test.precision (x FLOAT(0))
diff --git a/pkg/sql/opt/exec/execbuilder/testdata/explain b/pkg/sql/opt/exec/execbuilder/testdata/explain
index 2e5663fa3630..11d2844f3355 100644
--- a/pkg/sql/opt/exec/execbuilder/testdata/explain
+++ b/pkg/sql/opt/exec/execbuilder/testdata/explain
@@ -598,11 +598,37 @@ vectorized: true
│
└── • render
│
- └── • filter
- │ filter: ((table_catalog = 'test') AND (table_schema = 'public')) AND (table_name = 'foo')
+ └── • virtual table lookup join
+ │ table: pg_namespace@pg_namespace_oid_idx
+ │ equality: (relnamespace) = (oid)
+ │ pred: nspname = index_schema
│
- └── • virtual table
- table: statistics@primary
+ └── • hash join
+ │ equality: (indexrelid, indrelid) = (oid, oid)
+ │
+ ├── • virtual table
+ │ table: pg_index@primary
+ │
+ └── • hash join
+ │ equality: (relname, relnamespace) = (index_name, relnamespace)
+ │
+ ├── • virtual table
+ │ table: pg_class@primary
+ │
+ └── • merge join
+ │ equality: (relname) = (table_name)
+ │
+ ├── • filter
+ │ │ filter: relname = 'foo'
+ │ │
+ │ └── • virtual table
+ │ table: pg_class@primary
+ │
+ └── • filter
+ │ filter: ((table_name = 'foo') AND (table_catalog = 'test')) AND (table_schema = 'public')
+ │
+ └── • virtual table
+ table: statistics@primary
query T
EXPLAIN SHOW CONSTRAINTS FROM foo
diff --git a/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index b/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index
index caf490867b7d..bd89c4e77787 100644
--- a/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index
+++ b/pkg/sql/opt/exec/execbuilder/testdata/not_visible_index
@@ -75,12 +75,12 @@ t1_pkey v true
t1_pkey i true
# Check System Descriptor.
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW INDEX FROM system.descriptor]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-descriptor primary false 1 id ASC false false true
-descriptor primary false 2 descriptor N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+descriptor primary false 1 id id ASC false false true
+descriptor primary false 2 descriptor descriptor N/A true false true
query TT
SELECT cols.desc->>'name', cols.desc->>'notVisible' FROM (
@@ -1198,16 +1198,16 @@ CREATE TABLE t1 (
INDEX idx_invisible (other) NOT VISIBLE
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW INDEX FROM t1]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t1 t1_pkey false 1 c ASC false false true
-t1 t1_pkey false 2 other N/A true false true
-t1 idx_visible true 1 other ASC false false true
-t1 idx_visible true 2 c ASC false true true
-t1 idx_invisible true 1 other ASC false false false
-t1 idx_invisible true 2 c ASC false true false
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t1 t1_pkey false 1 c c ASC false false true
+t1 t1_pkey false 2 other other N/A true false true
+t1 idx_visible true 1 other other ASC false false true
+t1 idx_visible true 2 c c ASC false true true
+t1 idx_invisible true 1 other other ASC false false false
+t1 idx_invisible true 2 c c ASC false true false
# Primary index cannot be invisible.
statement error pq: primary index cannot be invisible
@@ -1228,16 +1228,16 @@ ALTER TABLE t1 ALTER PRIMARY KEY USING COLUMNS (other);
# A new primary index t1_pkey is created on the column other. The old primary
# index becomes a secondary index t1_c_key on c. idx_invisible remains
# invisible.
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW INDEX FROM t1]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t1 t1_pkey false 1 other ASC false false true
-t1 t1_pkey false 2 c N/A true false true
-t1 t1_c_key false 1 c ASC false false true
-t1 t1_c_key false 2 other ASC true true true
-t1 idx_visible true 1 other ASC false false true
-t1 idx_invisible true 1 other ASC false false false
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t1 t1_pkey false 1 other other ASC false false true
+t1 t1_pkey false 2 c c N/A true false true
+t1 t1_c_key false 1 c c ASC false false true
+t1 t1_c_key false 2 other other ASC true true true
+t1 idx_visible true 1 other other ASC false false true
+t1 idx_invisible true 1 other other ASC false false false
# Changing the old primary key index t1_c_key (secondary index now) to invisible
# is fine.
@@ -1531,15 +1531,15 @@ statement ok
CREATE INDEX v_idx on t(k);
ALTER INDEX v_idx INVISIBLE
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SELECT * FROM [SHOW INDEX FROM t]
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t t_pkey false 1 p ASC false false true
-t t_pkey false 2 k N/A true false true
-t t_pkey false 3 v N/A true false true
-t p_idx true 1 p ASC false false false
-t k_idx true 1 k ASC false false false
-t k_idx true 2 p ASC false true false
-t v_idx true 1 k ASC false false false
-t v_idx true 2 p ASC false true false
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t t_pkey false 1 p p ASC false false true
+t t_pkey false 2 k k N/A true false true
+t t_pkey false 3 v v N/A true false true
+t p_idx true 1 p p ASC false false false
+t k_idx true 1 k k ASC false false false
+t k_idx true 2 p p ASC false true false
+t v_idx true 1 k k ASC false false false
+t v_idx true 2 p p ASC false true false
diff --git a/pkg/sql/opt/exec/execbuilder/testdata/select b/pkg/sql/opt/exec/execbuilder/testdata/select
index a86f0a05bb87..887e8eaeeeac 100644
--- a/pkg/sql/opt/exec/execbuilder/testdata/select
+++ b/pkg/sql/opt/exec/execbuilder/testdata/select
@@ -540,22 +540,22 @@ CREATE TABLE t (
FAMILY (a, b, c, d)
)
-query TTBITTBBB colnames
+query TTBITTTBBB colnames
SHOW INDEXES FROM t
----
-table_name index_name non_unique seq_in_index column_name direction storing implicit visible
-t b_idx true 1 b ASC false false true
-t b_idx true 2 c N/A true false true
-t b_idx true 3 d N/A true false true
-t b_idx true 4 a ASC false true true
-t c_idx false 1 c ASC false false true
-t c_idx false 2 b N/A true false true
-t c_idx false 3 d N/A true false true
-t c_idx false 4 a ASC true 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
-t t_pkey false 4 d N/A true false true
+table_name index_name non_unique seq_in_index column_name definition direction storing implicit visible
+t b_idx true 1 b b ASC false false true
+t b_idx true 2 c c N/A true false true
+t b_idx true 3 d d N/A true false true
+t b_idx true 4 a a ASC false true true
+t c_idx false 1 c c ASC false false true
+t c_idx false 2 b b N/A true false true
+t c_idx false 3 d d N/A true false true
+t c_idx false 4 a a ASC true true true
+t t_pkey false 1 a a ASC false false true
+t t_pkey false 2 b b N/A true false true
+t t_pkey false 3 c c N/A true false true
+t t_pkey false 4 d d N/A true false true
statement ok
INSERT INTO t VALUES (1, 2, 3, 4)
diff --git a/pkg/sql/opt/exec/execbuilder/testdata/select_index b/pkg/sql/opt/exec/execbuilder/testdata/select_index
index 57876c0cfcc3..cee875c62368 100644
--- a/pkg/sql/opt/exec/execbuilder/testdata/select_index
+++ b/pkg/sql/opt/exec/execbuilder/testdata/select_index
@@ -753,15 +753,15 @@ vectorized: true
# Check that primary key definitions can indicate index ordering,
# and this information is subsequently used during index selection
# and span generation. #13882
-query TTBITTBBB
+query TTBITTTBBB
CREATE TABLE abz(a INT, b INT, c INT, PRIMARY KEY (a DESC, b ASC), UNIQUE(c DESC, b ASC)); SHOW INDEX FROM abz
----
-abz abz_c_b_key false 1 c DESC false false true
-abz abz_c_b_key false 2 b ASC false false true
-abz abz_c_b_key false 3 a ASC true true true
-abz abz_pkey false 1 a DESC false false true
-abz abz_pkey false 2 b ASC false false true
-abz abz_pkey false 3 c N/A true false true
+abz abz_c_b_key false 1 c c DESC false false true
+abz abz_c_b_key false 2 b b ASC false false true
+abz abz_c_b_key false 3 a a ASC true true true
+abz abz_pkey false 1 a a DESC false false true
+abz abz_pkey false 2 b b ASC false false true
+abz abz_pkey false 3 c c N/A true false true
query T
EXPLAIN (VERBOSE) SELECT a FROM abz ORDER BY a DESC LIMIT 1
diff --git a/pkg/sql/pgwire/pgwire_test.go b/pkg/sql/pgwire/pgwire_test.go
index bd40b664f39c..854012e84091 100644
--- a/pkg/sql/pgwire/pgwire_test.go
+++ b/pkg/sql/pgwire/pgwire_test.go
@@ -561,12 +561,12 @@ func TestPGPreparedQuery(t *testing.T) {
Results("system", "public", "users", username.RootUser, "UPDATE", true),
}},
{"SHOW INDEXES FROM system.users", []preparedQueryTest{
- baseTest.Results("users", "primary", false, 1, "username", "ASC", false, false, true).
- Results("users", "primary", false, 2, "hashedPassword", "N/A", true, false, true).
- Results("users", "primary", false, 3, "isRole", "N/A", true, false, true).
- Results("users", "primary", false, 4, "user_id", "N/A", true, false, true).
- Results("users", "users_user_id_idx", false, 1, "user_id", "ASC", false, false, true).
- Results("users", "users_user_id_idx", false, 2, "username", "ASC", true, true, true),
+ baseTest.Results("users", "primary", false, 1, "username", "username", "ASC", false, false, true).
+ Results("users", "primary", false, 2, "hashedPassword", "hashedPassword", "N/A", true, false, true).
+ Results("users", "primary", false, 3, "isRole", "isRole", "N/A", true, false, true).
+ Results("users", "primary", false, 4, "user_id", "user_id", "N/A", true, false, true).
+ Results("users", "users_user_id_idx", false, 1, "user_id", "user_id", "ASC", false, false, true).
+ Results("users", "users_user_id_idx", false, 2, "username", "username", "ASC", true, true, true),
}},
{"SHOW TABLES FROM system", []preparedQueryTest{
baseTest.Results("public", "comments", "table", gosql.NullString{}, 0, gosql.NullString{}).Others(bootstrap.NumSystemTablesForSystemTenant - 1),
|