Skip to content

Commit

Permalink
sql: support SHOW GRANTS for user-defined functions
Browse files Browse the repository at this point in the history
Backport resolves #88495

Release note (sql change): Previously `SHOW GRANTS` only supports
db, schema, table and types. This commit add supports for UDFs,
so that `SHOW GRANTS` returns UDFs privileges infos, and statements
like `SHOW GRANTS ON FUNCTION <udf name/signatures>` are now supported
Full function signature must be provided if the function name is
not unique.
Release justification: low risk GA blocker.
  • Loading branch information
chengxiong-ruan committed Sep 27, 2022
1 parent beb40b5 commit 588d477
Show file tree
Hide file tree
Showing 3 changed files with 231 additions and 0 deletions.
2 changes: 2 additions & 0 deletions pkg/sql/delegate/BUILD.bazel
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,7 @@ go_library(
"//pkg/sql/catalog/colinfo",
"//pkg/sql/decodeusername",
"//pkg/sql/lexbase",
"//pkg/sql/oidext",
"//pkg/sql/opt/cat",
"//pkg/sql/parser",
"//pkg/sql/pgwire/pgcode",
Expand All @@ -58,6 +59,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",
],
Expand Down
60 changes: 60 additions & 0 deletions pkg/sql/delegate/show_grants.go
Original file line number Diff line number Diff line change
Expand Up @@ -13,15 +13,18 @@ package delegate
import (
"bytes"
"fmt"
"strconv"
"strings"

"github.com/cockroachdb/cockroach/pkg/security/username"
"github.com/cockroachdb/cockroach/pkg/sql/decodeusername"
"github.com/cockroachdb/cockroach/pkg/sql/lexbase"
"github.com/cockroachdb/cockroach/pkg/sql/oidext"
"github.com/cockroachdb/cockroach/pkg/sql/opt/cat"
"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
Expand Down Expand Up @@ -100,6 +103,34 @@ SELECT *
) AS a
)
`
// Query grants data for user-defined functions. Builtin functions are not
// included.
udfQuery := fmt.Sprintf(`
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 > %d
)
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
`, oidext.CockroachPredefinedOIDMax)

var source bytes.Buffer
var cond bytes.Buffer
Expand Down Expand Up @@ -217,6 +248,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)
Expand Down Expand Up @@ -284,6 +340,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))
Expand Down
169 changes: 169 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/udf
Original file line number Diff line number Diff line change
Expand Up @@ -605,6 +605,7 @@ 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 $$;
Expand All @@ -620,6 +621,22 @@ NULL root test public test_priv_f1_100137 test
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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

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;

Expand All @@ -636,6 +653,17 @@ NULL udf_test_user test public test_priv_f1_100137
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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 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;

Expand All @@ -655,6 +683,17 @@ NULL udf_test_user test public test_priv_f1_100137
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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 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;

Expand All @@ -668,6 +707,14 @@ NULL root test public test_priv_f1_100137 test
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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 ALL FUNCTIONS IN SCHEMA public, test_priv_sc1 TO udf_test_user WITH GRANT OPTION;

Expand All @@ -684,6 +731,17 @@ NULL udf_test_user test public test_priv_f1_100137
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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 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;

Expand All @@ -700,6 +758,17 @@ NULL udf_test_user test public test_priv_f1_100137
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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 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;

Expand All @@ -713,6 +782,14 @@ NULL root test public test_priv_f1_100137 test
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, 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
DROP FUNCTION test_priv_f1;
DROP FUNCTION test_priv_f2;
Expand All @@ -733,6 +810,12 @@ ORDER BY grantee, routine_name;
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1
----
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
ALTER DEFAULT PRIVILEGES IN SCHEMA public, test_priv_sc1 GRANT EXECUTE ON FUNCTIONS TO udf_test_user WITH GRANT OPTION;
Expand All @@ -753,6 +836,16 @@ NULL root test test_priv_sc1 test_priv_f3_100142
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3
----
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;
Expand All @@ -765,6 +858,12 @@ ORDER BY grantee, routine_name;
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1
----
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;

Expand All @@ -782,6 +881,17 @@ NULL root test public test_priv_f1_100140 test
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

query TTTTTTB colnames
SHOW GRANTS ON FUNCTION test_priv_f1, test_priv_f2, test_priv_f3
----
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

statement ok
Expand Down Expand Up @@ -1601,6 +1711,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
Expand Down

0 comments on commit 588d477

Please sign in to comment.