diff --git a/pkg/sql/delegate/BUILD.bazel b/pkg/sql/delegate/BUILD.bazel index b9ae041544fa..8bfd137ed151 100644 --- a/pkg/sql/delegate/BUILD.bazel +++ b/pkg/sql/delegate/BUILD.bazel @@ -58,6 +58,7 @@ go_library( "//pkg/sql/sem/eval", "//pkg/sql/sem/tree", "//pkg/sql/sqltelemetry", + "//pkg/util", "//pkg/util/errorutil/unimplemented", "@com_github_cockroachdb_errors//:errors", ], diff --git a/pkg/sql/delegate/show_grants.go b/pkg/sql/delegate/show_grants.go index 4c7a72d78bdc..081a87ef1d7f 100644 --- a/pkg/sql/delegate/show_grants.go +++ b/pkg/sql/delegate/show_grants.go @@ -13,6 +13,7 @@ package delegate import ( "bytes" "fmt" + "strconv" "strings" "github.com/cockroachdb/cockroach/pkg/security/username" @@ -22,6 +23,7 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/pgwire/pgcode" "github.com/cockroachdb/cockroach/pkg/sql/pgwire/pgerror" "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" + "github.com/cockroachdb/cockroach/pkg/util" ) // delegateShowGrants implements SHOW GRANTS which returns grant details for the @@ -100,6 +102,33 @@ SELECT * ) AS a ) ` + // + const udfQuery = ` +WITH fn_grants AS ( + SELECT routine_catalog as database_name, + routine_schema as schema_name, + reverse(split_part(reverse(specific_name), '_', 1))::OID as function_id, + routine_name as function_name, + grantee, + privilege_type, + is_grantable::boolean + FROM "".information_schema.role_routine_grants + WHERE reverse(split_part(reverse(specific_name), '_', 1))::INT > 100000 +) +SELECT database_name, + schema_name, + function_id, + concat( + function_name, + '(', + pg_get_function_identity_arguments(function_id), + ')' + ) as function_signature, + grantee, + privilege_type, + is_grantable + FROM fn_grants +` var source bytes.Buffer var cond bytes.Buffer @@ -217,6 +246,31 @@ SELECT * strings.Join(params, ","), ) } + } else if n.Targets != nil && len(n.Targets.Functions) > 0 { + fmt.Fprint(&source, udfQuery) + orderBy = "1,2,3,4,5,6" + fnResolved := util.MakeFastIntSet() + for _, fn := range n.Targets.Functions { + un := fn.FuncName.ToUnresolvedObjectName().ToUnresolvedName() + fd, err := d.catalog.ResolveFunction(d.ctx, un, &d.evalCtx.SessionData().SearchPath) + if err != nil { + return nil, err + } + argTypes, err := fn.InputArgTypes(d.ctx, d.catalog) + if err != nil { + return nil, err + } + ol, err := fd.MatchOverload(argTypes, fn.FuncName.Schema(), &d.evalCtx.SessionData().SearchPath) + if err != nil { + return nil, err + } + fnResolved.Add(int(ol.Oid)) + } + params = make([]string, fnResolved.Len()) + for i, fnID := range fnResolved.Ordered() { + params[i] = strconv.Itoa(fnID) + } + fmt.Fprintf(&cond, `WHERE function_id IN (%s)`, strings.Join(params, ",")) } else if n.Targets != nil && n.Targets.System { orderBy = "1,2,3" fmt.Fprint(&source, systemPrivilegeQuery) @@ -284,6 +338,10 @@ SELECT * `SELECT database_name, schema_name, type_name AS relation_name, grantee, privilege_type, is_grantable FROM (`) source.WriteString(typePrivQuery) source.WriteByte(')') + source.WriteString(` UNION ALL ` + + `SELECT database_name, schema_name, function_signature AS relation_name, grantee, privilege_type, is_grantable FROM (`) + source.WriteString(udfQuery) + source.WriteByte(')') // If the current database is set, restrict the command to it. if currDB := d.evalCtx.SessionData().Database; currDB != "" { fmt.Fprintf(&cond, ` WHERE database_name = %s`, lexbase.EscapeSQLString(currDB)) diff --git a/pkg/sql/logictest/testdata/logic_test/udf b/pkg/sql/logictest/testdata/logic_test/udf index cd32bbe5143c..112d71c0c3bc 100644 --- a/pkg/sql/logictest/testdata/logic_test/udf +++ b/pkg/sql/logictest/testdata/logic_test/udf @@ -605,36 +605,41 @@ subtest grant_revoke statement ok CREATE SCHEMA test_priv_sc1; +SET search_path = public,test_priv_sc1; CREATE FUNCTION test_priv_f1() RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; CREATE FUNCTION test_priv_f2(int) RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; CREATE FUNCTION test_priv_sc1.test_priv_f3() RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; CREATE USER udf_test_user; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true + +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1(), test_priv_f2(INT), test_priv_f3() +---- +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true statement ok GRANT EXECUTE ON FUNCTION test_priv_f1(), test_priv_f2(int), test_priv_sc1.test_priv_f3 TO udf_test_user WITH GRANT OPTION; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES -NULL udf_test_user test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL udf_test_user test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL udf_test_user test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100137 test_priv_f1() udf_test_user EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test public 100138 test_priv_f2(int8) udf_test_user EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() udf_test_user EXECUTE true statement error pq: cannot drop role/user udf_test_user: grants still exist on.* DROP USER udf_test_user; @@ -642,76 +647,66 @@ DROP USER udf_test_user; statement ok REVOKE GRANT OPTION FOR EXECUTE ON FUNCTION test_priv_f1(), test_priv_f2(int), test_priv_sc1.test_priv_f3 FROM udf_test_user; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES -NULL udf_test_user test public test_priv_f1_100137 test public test_priv_f1 EXECUTE NO -NULL udf_test_user test public test_priv_f2_100138 test public test_priv_f2 EXECUTE NO -NULL udf_test_user test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE NO +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100137 test_priv_f1() udf_test_user EXECUTE false +test public 100138 test_priv_f2(int8) root EXECUTE true +test public 100138 test_priv_f2(int8) udf_test_user EXECUTE false +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() udf_test_user EXECUTE false statement ok REVOKE EXECUTE ON FUNCTION test_priv_f1(), test_priv_f2(int), test_priv_sc1.test_priv_f3 FROM udf_test_user; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true statement ok GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public, test_priv_sc1 TO udf_test_user WITH GRANT OPTION; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES -NULL udf_test_user test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL udf_test_user test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL udf_test_user test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100137 test_priv_f1() udf_test_user EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test public 100138 test_priv_f2(int8) udf_test_user EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() udf_test_user EXECUTE true statement ok REVOKE GRANT OPTION FOR EXECUTE ON ALL FUNCTIONS in schema public, test_priv_sc1 FROM udf_test_user; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES -NULL udf_test_user test public test_priv_f1_100137 test public test_priv_f1 EXECUTE NO -NULL udf_test_user test public test_priv_f2_100138 test public test_priv_f2 EXECUTE NO -NULL udf_test_user test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE NO +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100137 test_priv_f1() udf_test_user EXECUTE false +test public 100138 test_priv_f2(int8) root EXECUTE true +test public 100138 test_priv_f2(int8) udf_test_user EXECUTE false +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() udf_test_user EXECUTE false statement ok REVOKE EXECUTE ON ALL FUNCTIONS IN SCHEMA public, test_priv_sc1 FROM udf_test_user; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100137 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100138 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100139 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100137 test_priv_f1() root EXECUTE true +test public 100138 test_priv_f2(int8) root EXECUTE true +test test_priv_sc1 100139 test_priv_f3() root EXECUTE true statement ok DROP FUNCTION test_priv_f1; @@ -725,13 +720,11 @@ statement ok CREATE USER udf_test_user; CREATE FUNCTION test_priv_f1() RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100140 test public test_priv_f1 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100140 test_priv_f1() root EXECUTE true # Add default privilege and make sure new function statement ok @@ -741,29 +734,25 @@ statement ok CREATE FUNCTION test_priv_f2(int) RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; CREATE FUNCTION test_priv_sc1.test_priv_f3() RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100140 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100141 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100142 test test_priv_sc1 test_priv_f3 EXECUTE YES -NULL udf_test_user test public test_priv_f2_100141 test public test_priv_f2 EXECUTE YES -NULL udf_test_user test test_priv_sc1 test_priv_f3_100142 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100140 test_priv_f1() root EXECUTE true +test public 100141 test_priv_f2(int8) root EXECUTE true +test public 100141 test_priv_f2(int8) udf_test_user EXECUTE true +test test_priv_sc1 100142 test_priv_f3() root EXECUTE true +test test_priv_sc1 100142 test_priv_f3() udf_test_user EXECUTE true statement ok DROP FUNCTION test_priv_f2; DROP FUNCTION test_priv_sc1.test_priv_f3; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100140 test public test_priv_f1 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100140 test_priv_f1() root EXECUTE true statement ok ALTER DEFAULT PRIVILEGES IN SCHEMA public, test_priv_sc1 REVOKE EXECUTE ON FUNCTIONS FROM udf_test_user; @@ -772,15 +761,16 @@ statement ok CREATE FUNCTION test_priv_f2(int) RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; CREATE FUNCTION test_priv_sc1.test_priv_f3() RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; -query TTTTTTTTTT colnames -SELECT * FROM information_schema.role_routine_grants -WHERE routine_name IN ('test_priv_f1', 'test_priv_f2', 'test_priv_f3') -ORDER BY grantee, routine_name; +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3 ---- -grantor grantee specific_catalog specific_schema specific_name routine_catalog routine_schema routine_name privilege_type is_grantable -NULL root test public test_priv_f1_100140 test public test_priv_f1 EXECUTE YES -NULL root test public test_priv_f2_100143 test public test_priv_f2 EXECUTE YES -NULL root test test_priv_sc1 test_priv_f3_100144 test test_priv_sc1 test_priv_f3 EXECUTE YES +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test public 100140 test_priv_f1() root EXECUTE true +test public 100143 test_priv_f2(int8) root EXECUTE true +test test_priv_sc1 100144 test_priv_f3() root EXECUTE true + +statement ok +SET search_path = public; subtest alter_function_options @@ -1601,6 +1591,65 @@ SELECT etype, info_json->'DescriptorID', info_json->'FunctionName', info_json->' ---- drop_function 203 "test.public.f_test_log" "DROP FUNCTION \"\".\"\".f_test_log" +subtest show_grants + +statement ok +CREATE SCHEMA sc_test_show_grants; +SET search_path = sc_test_show_grants; +CREATE FUNCTION f_test_show_grants(INT) RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; +CREATE FUNCTION f_test_show_grants(INT, string, OID) RETURNS INT LANGUAGE SQL AS $$ SELECT 1 $$; +CREATE USER u_test_show_grants; +GRANT EXECUTE ON FUNCTION f_test_show_grants(INT), f_test_show_grants(INT, string, OID) TO u_test_show_grants; + +statement error pq: function name "f_test_show_grants" is not unique +SHOW GRANTS ON FUNCTION f_test_show_grants; + +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION f_test_show_grants(INT), f_test_show_grants(INT, string, OID); +---- +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test sc_test_show_grants 100205 f_test_show_grants(int8) root EXECUTE true +test sc_test_show_grants 100205 f_test_show_grants(int8) u_test_show_grants EXECUTE false +test sc_test_show_grants 100206 f_test_show_grants(int8, text, oid) root EXECUTE true +test sc_test_show_grants 100206 f_test_show_grants(int8, text, oid) u_test_show_grants EXECUTE false + +statement error pq: function f_test_show_grants\(string\) does not exist: function undefined +SHOW GRANTS ON FUNCTION f_test_show_grants(string); + +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION f_test_show_grants(INT) +---- +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test sc_test_show_grants 100205 f_test_show_grants(int8) root EXECUTE true +test sc_test_show_grants 100205 f_test_show_grants(int8) u_test_show_grants EXECUTE false + +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION f_test_show_grants(INT, string, OID); +---- +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test sc_test_show_grants 100206 f_test_show_grants(int8, text, oid) root EXECUTE true +test sc_test_show_grants 100206 f_test_show_grants(int8, text, oid) u_test_show_grants EXECUTE false + +statement error pq: unknown function: f_not_existing\(\): function undefined +SHOW GRANTS ON FUNCTION f_not_existing; + +query TTTTTTB colnames +SHOW GRANTS ON FUNCTION f_test_show_grants(INT), f_test_show_grants(INT, string, OID) FOR u_test_show_grants; +---- +database_name schema_name function_id function_signature grantee privilege_type is_grantable +test sc_test_show_grants 100205 f_test_show_grants(int8) u_test_show_grants EXECUTE false +test sc_test_show_grants 100206 f_test_show_grants(int8, text, oid) u_test_show_grants EXECUTE false + +query TTTTTB colnames +SHOW GRANTS FOR u_test_show_grants; +---- +database_name schema_name relation_name grantee privilege_type is_grantable +test sc_test_show_grants f_test_show_grants(int8) u_test_show_grants EXECUTE false +test sc_test_show_grants f_test_show_grants(int8, text, oid) u_test_show_grants EXECUTE false + +statement ok +SET search_path = public; + subtest execution statement ok