Skip to content

sql: portable SHOW CREATE FUNCTION output #148746

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

Merged
merged 1 commit into from
Jun 26, 2025
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
8 changes: 4 additions & 4 deletions pkg/backup/testdata/backup-restore/plpgsql_procedures
Original file line number Diff line number Diff line change
Expand Up @@ -99,7 +99,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
DECLARE
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
END;
Expand Down Expand Up @@ -140,7 +140,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
DECLARE
foobar sc1.enum1;
BEGIN
SELECT a FROM db1_new.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
END;
Expand Down Expand Up @@ -307,7 +307,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
DECLARE
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
END;
Expand Down Expand Up @@ -349,7 +349,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
DECLARE
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
END;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -121,7 +121,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
x INT8 := 0;
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
RETURN nextval('sc1.sq1'::REGCLASS);
END;
Expand All @@ -146,7 +146,7 @@ CREATE FUNCTION sc2.f2()
DECLARE
x INT8;
BEGIN
SELECT a FROM db1.sc2.tbl2 LIMIT 1 INTO x;
SELECT a FROM sc2.tbl2 LIMIT 1 INTO x;
SELECT sc1.f1('Good':::sc1.enum1);
CALL public.p_nested('Good':::sc1.enum1);
RETURN x;
Expand Down Expand Up @@ -184,7 +184,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
x INT8 := 0;
foobar sc1.enum1;
BEGIN
SELECT a FROM db1_new.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
RETURN nextval('sc1.sq1'::REGCLASS);
END;
Expand All @@ -204,7 +204,7 @@ CREATE FUNCTION sc2.f2()
DECLARE
x INT8;
BEGIN
SELECT a FROM db1_new.sc2.tbl2 LIMIT 1 INTO x;
SELECT a FROM sc2.tbl2 LIMIT 1 INTO x;
SELECT sc1.f1('Good':::sc1.enum1);
CALL public.p_nested('Good':::sc1.enum1);
RETURN x;
Expand Down Expand Up @@ -376,7 +376,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
x INT8;
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS) INTO x;
RETURN x;
Expand Down Expand Up @@ -420,7 +420,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
x INT8;
foobar sc1.enum1;
BEGIN
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS) INTO x;
RETURN x;
Expand Down
8 changes: 4 additions & 4 deletions pkg/backup/testdata/backup-restore/procedures
Original file line number Diff line number Diff line change
Expand Up @@ -90,7 +90,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -127,7 +127,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1_new.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -284,7 +284,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -322,7 +322,7 @@ CREATE PROCEDURE sc1.p1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down
8 changes: 4 additions & 4 deletions pkg/backup/testdata/backup-restore/user-defined-functions
Original file line number Diff line number Diff line change
Expand Up @@ -93,7 +93,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -130,7 +130,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1_new.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -279,7 +279,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down Expand Up @@ -317,7 +317,7 @@ CREATE FUNCTION sc1.f1(a sc1.enum1)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM db1.sc1.tbl1;
SELECT a FROM sc1.tbl1;
SELECT 'Good':::sc1.enum1;
SELECT nextval('sc1.sq1'::REGCLASS);
$$
Expand Down
5 changes: 5 additions & 0 deletions pkg/sql/crdb_internal.go
Original file line number Diff line number Diff line change
Expand Up @@ -3555,6 +3555,11 @@ func createRoutinePopulate(
if err != nil {
return err
}
bodyStr, err = formatUnqualifyTableNames(bodyStr, fnIDToDBName[fnDesc.GetID()], fnDesc.GetLanguage())
if err != nil {
return err
}

bodyStr = strings.TrimSpace(bodyStr)
stmtStrs := strings.Split(bodyStr, "\n")
for i := range stmtStrs {
Expand Down
48 changes: 48 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/show_create_all_routines
Original file line number Diff line number Diff line change
Expand Up @@ -162,3 +162,51 @@ CREATE FUNCTION s.add_one(x INT8)
AS $$
SELECT x + 1;
$$;

subtest trigger_invalid_reference
# ensure the lazily evaluated function bodies parse

statement ok
CREATE FUNCTION select_invalid() RETURNS TRIGGER AS $$
BEGIN
SELECT 1 FROM a.b.c;
END;
$$ LANGUAGE PLpgSQL;

query T
SELECT * FROM [SHOW CREATE ALL ROUTINES] ORDER BY 1;
----
CREATE FUNCTION public.add_one(x INT8)
RETURNS INT8
VOLATILE
NOT LEAKPROOF
CALLED ON NULL INPUT
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT x + 1;
$$;
CREATE FUNCTION public.select_invalid()
RETURNS TRIGGER
VOLATILE
NOT LEAKPROOF
CALLED ON NULL INPUT
LANGUAGE plpgsql
SECURITY INVOKER
AS $$
BEGIN
SELECT 1 FROM a.b.c;
END;
$$;
CREATE FUNCTION s.add_one(x INT8)
RETURNS INT8
VOLATILE
NOT LEAKPROOF
CALLED ON NULL INPUT
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT x + 1;
$$;

subtest end
6 changes: 3 additions & 3 deletions pkg/sql/logictest/testdata/logic_test/udf
Original file line number Diff line number Diff line change
Expand Up @@ -106,9 +106,9 @@ CREATE FUNCTION public.f(a public.notmyworkday)
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT a FROM test.public.t;
SELECT b FROM test.public.t@t_idx_b;
SELECT c FROM test.public.t@t_idx_c;
SELECT a FROM public.t;
SELECT b FROM public.t@t_idx_b;
SELECT c FROM public.t@t_idx_c;
SELECT nextval('public.sq1'::REGCLASS);
$$

Expand Down
35 changes: 34 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/udf_record
Original file line number Diff line number Diff line change
Expand Up @@ -82,7 +82,7 @@ f_table CREATE FUNCTION public.f_table()
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT t.a, t.b FROM test.public.t ORDER BY a LIMIT 1;
SELECT t.a, t.b FROM public.t ORDER BY a LIMIT 1;
$$

query T
Expand Down Expand Up @@ -130,6 +130,39 @@ SELECT f_table();
----
(1,5)

subtest unqualifying_table_names
# test case-sensitive and unicode database names

statement ok
CREATE DATABASE "interesting⨄DbName";
USE "interesting⨄DbName";
CREATE TABLE t1 (c1 int);

statement ok
CREATE FUNCTION f() RETURNS INT VOLATILE LANGUAGE SQL AS
$$
SELECT * FROM t1;
$$;

query TT
SHOW CREATE FUNCTION f;
----
f CREATE FUNCTION public.f()
RETURNS INT8
VOLATILE
NOT LEAKPROOF
CALLED ON NULL INPUT
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT t1.c1 FROM public.t1;
$$


statement ok
USE test;

subtest end

subtest datasource

Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/logictest/testdata/logic_test/udf_regressions
Original file line number Diff line number Diff line change
Expand Up @@ -520,7 +520,7 @@ CREATE FUNCTION public.func104242()
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT 1 FROM test.public.tab104242 WHERE NULL IN ();
SELECT 1 FROM public.tab104242 WHERE NULL IN ();
$$

statement ok
Expand All @@ -539,7 +539,7 @@ CREATE FUNCTION public.func104242_not_null()
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT 1 FROM test.public.tab104242 WHERE 'foo':::public.typ104242 IN ();
SELECT 1 FROM public.tab104242 WHERE 'foo':::public.typ104242 IN ();
$$

subtest end
Expand Down
4 changes: 2 additions & 2 deletions pkg/sql/logictest/testdata/logic_test/udf_star
Original file line number Diff line number Diff line change
Expand Up @@ -113,7 +113,7 @@ f_subquery CREATE FUNCTION public.f_subquery()
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT bar.a FROM (SELECT a FROM (SELECT t_onecol.a FROM test.public.t_onecol) AS foo) AS bar;
SELECT bar.a FROM (SELECT a FROM (SELECT t_onecol.a FROM public.t_onecol) AS foo) AS bar;
$$

query TT
Expand All @@ -127,7 +127,7 @@ f_allcolsel_alias CREATE FUNCTION public.f_allcolsel_alias()
LANGUAGE SQL
SECURITY INVOKER
AS $$
SELECT t1.a, t1.b FROM test.public.t_twocol AS t1, test.public.t_twocol AS t2 WHERE t1.a = t2.a;
SELECT t1.a, t1.b FROM public.t_twocol AS t1, public.t_twocol AS t2 WHERE t1.a = t2.a;
$$

query I
Expand Down
2 changes: 1 addition & 1 deletion pkg/sql/sem/tree/format.go
Original file line number Diff line number Diff line change
Expand Up @@ -430,7 +430,7 @@ func (ctx *FmtCtx) SetLocation(loc *time.Location) *time.Location {
return old
}

// WithReformatTableNames modifies FmtCtx to to substitute the printing of table
// WithReformatTableNames modifies FmtCtx to substitute the printing of table
// names using the provided function, calls fn, then restores the original table
// formatting.
func (ctx *FmtCtx) WithReformatTableNames(tableNameFmt func(*FmtCtx, *TableName), fn func()) {
Expand Down
57 changes: 57 additions & 0 deletions pkg/sql/show_create_clauses.go
Original file line number Diff line number Diff line change
Expand Up @@ -273,6 +273,63 @@ func formatQuerySequencesForDisplay(
return fmtCtx.CloseAndGetString(), nil
}

// Drops the database component of the table names (i.e. unqualifies) when it matches the name provided.
func formatUnqualifyTableNames(
queries string, databaseName string, lang catpb.Function_Language,
) (string, error) {

// walking the table names using the reformat option. the buffer is simply discarded
unqualifyTableNamesCtx := tree.NewFmtCtx(tree.FmtSimple, tree.FmtReformatTableNames(func(ctx *tree.FmtCtx, tn *tree.TableName) {
if string(tn.CatalogName) == databaseName {
tn.ExplicitCatalog = false
}
}))
defer unqualifyTableNamesCtx.Close()

// a fresh buffer to rebuild the queries string
prettyPrintCtx := tree.NewFmtCtx(tree.FmtSimple)

switch lang {
case catpb.Function_SQL:
parsedStmts, err := parser.Parse(queries)
if err != nil {
return "", err
}

stmts := make(tree.Statements, len(parsedStmts))
for i, stmt := range parsedStmts {
stmts[i] = stmt.AST
}

for _, stmt := range stmts {
unqualifyTableNamesCtx.FormatNode(stmt)
}

for i, stmt := range stmts {
if i > 0 {
prettyPrintCtx.WriteString("\n")
}
prettyPrintCtx.FormatNode(stmt)
prettyPrintCtx.WriteString(";")
}
case catpb.Function_PLPGSQL:
var stmts plpgsqltree.Statement
plstmt, err := plpgsql.Parse(queries)
if err != nil {
return "", err
}
stmts = plstmt.AST

unqualifyTableNamesCtx.FormatNode(stmts)

prettyPrintCtx.FormatNode(stmts)
default:
return queries, nil
}

return prettyPrintCtx.CloseAndGetString(), nil
}

// formatViewQueryTypesForDisplay walks the view query and
// look for serialized user-defined types. If it finds any,
// it will deserialize it to display its name.
Expand Down