Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

builtins: make pg_get_indexdef handle expression indexes #95413

Merged
merged 3 commits into from
Jan 20, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 4 additions & 0 deletions docs/generated/sql/functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -3538,6 +3538,10 @@ table. Returns an error if validation fails.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="pg_get_functiondef"></a><code>pg_get_functiondef(func_oid: oid) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>For user-defined functions, returns the definition of the specified function. For builtin functions, returns the name of the function.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="pg_get_indexdef"></a><code>pg_get_indexdef(index_oid: oid) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Gets the CREATE INDEX command for index</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="pg_get_indexdef"></a><code>pg_get_indexdef(index_oid: oid, column_no: <a href="int.html">int</a>, pretty_bool: <a href="bool.html">bool</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Gets the CREATE INDEX command for index, or definition of just one index column when given a non-zero column number</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="pg_get_serial_sequence"></a><code>pg_get_serial_sequence(table_name: <a href="string.html">string</a>, column_name: <a href="string.html">string</a>) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns the name of the sequence used by the given column_name in the table table_name.</p>
</span></td><td>Stable</td></tr>
<tr><td><a name="pg_get_viewdef"></a><code>pg_get_viewdef(view_oid: oid) &rarr; <a href="string.html">string</a></code></td><td><span class="funcdesc"><p>Returns the CREATE statement for an existing view.</p>
Expand Down
25 changes: 17 additions & 8 deletions pkg/sql/delegate/show_database_indexes.go
Original file line number Diff line number Diff line change
Expand Up @@ -31,28 +31,37 @@ 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,
is_visible::BOOL AS visible`

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`
Expand Down
25 changes: 16 additions & 9 deletions pkg/sql/delegate/show_table.go
Original file line number Diff line number Diff line change
Expand Up @@ -137,26 +137,33 @@ 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)]
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Ditto

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

adding

ELSE column_name
END AS definition,
direction,
storing::BOOL,
implicit::BOOL,
is_visible::BOOL AS visible`

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
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 @@ -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"},
},
)

Expand Down
6 changes: 3 additions & 3 deletions pkg/sql/logictest/testdata/logic_test/alter_primary_key
Original file line number Diff line number Diff line change
Expand Up @@ -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
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 @@ -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
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -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)
Expand Down
5 changes: 4 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/builtin_function
Original file line number Diff line number Diff line change
Expand Up @@ -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
·
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I don't understand what I'm seeing here. Could you explain in a review comment?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

. is what the test uses to represent the empty string. showing rowid in the result here was actually a bug. I've added that to the release note, and left a comment on the test to explain what is being tested.


query I
SELECT length(pg_catalog.pg_get_indexdef((SELECT oid from pg_class WHERE relname='pg_indexdef_cols_idx'), 4, false))
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 @@ -25,29 +25,29 @@ 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)

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

Expand All @@ -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)
Expand Down Expand Up @@ -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
Expand All @@ -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
Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/logictest/testdata/logic_test/create_table
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
Loading