Show default privileges in information schema
Hitherto, the information schema only showed explicitly granted privileges that were visible in the *acl catalog columns. If no privileges had been granted, the implicit privileges were not shown. To fix that, add an SQL-accessible version of the acldefault() function, and use that inside the aclexplode() calls to substitute the catalog-specific default privilege set for null values. reviewed by Abhijit Menon-Sen
This commit is contained in:
parent
bf90562aa4
commit
b376ec6fa5
@ -554,7 +554,7 @@ CREATE VIEW column_privileges AS
|
||||
pr_c.prtype,
|
||||
pr_c.grantable,
|
||||
pr_c.relowner
|
||||
FROM (SELECT oid, relname, relnamespace, relowner, (aclexplode(relacl)).*
|
||||
FROM (SELECT oid, relname, relnamespace, relowner, (aclexplode(coalesce(relacl, acldefault('r', relowner)))).*
|
||||
FROM pg_class
|
||||
WHERE relkind IN ('r', 'v', 'f')
|
||||
) pr_c (oid, relname, relnamespace, relowner, grantor, grantee, prtype, grantable),
|
||||
@ -571,8 +571,8 @@ CREATE VIEW column_privileges AS
|
||||
pr_a.prtype,
|
||||
pr_a.grantable,
|
||||
c.relowner
|
||||
FROM (SELECT attrelid, attname, (aclexplode(attacl)).*
|
||||
FROM pg_attribute
|
||||
FROM (SELECT attrelid, attname, (aclexplode(coalesce(attacl, acldefault('c', relowner)))).*
|
||||
FROM pg_attribute a JOIN pg_class cc ON (a.attrelid = cc.oid)
|
||||
WHERE attnum > 0
|
||||
AND NOT attisdropped
|
||||
) pr_a (attrelid, attname, grantor, grantee, prtype, grantable),
|
||||
@ -1276,7 +1276,7 @@ CREATE VIEW routine_privileges AS
|
||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||
|
||||
FROM (
|
||||
SELECT oid, proname, proowner, pronamespace, (aclexplode(proacl)).* FROM pg_proc
|
||||
SELECT oid, proname, proowner, pronamespace, (aclexplode(coalesce(proacl, acldefault('f', proowner)))).* FROM pg_proc
|
||||
) p (oid, proname, proowner, pronamespace, grantor, grantee, prtype, grantable),
|
||||
pg_namespace n,
|
||||
pg_authid u_grantor,
|
||||
@ -1797,7 +1797,7 @@ CREATE VIEW table_privileges AS
|
||||
CAST(CASE WHEN c.prtype = 'SELECT' THEN 'YES' ELSE 'NO' END AS yes_or_no) AS with_hierarchy
|
||||
|
||||
FROM (
|
||||
SELECT oid, relname, relnamespace, relkind, relowner, (aclexplode(relacl)).* FROM pg_class
|
||||
SELECT oid, relname, relnamespace, relkind, relowner, (aclexplode(coalesce(relacl, acldefault('r', relowner)))).* FROM pg_class
|
||||
) AS c (oid, relname, relnamespace, relkind, relowner, grantor, grantee, prtype, grantable),
|
||||
pg_namespace nc,
|
||||
pg_authid u_grantor,
|
||||
@ -2043,7 +2043,7 @@ CREATE VIEW udt_privileges AS
|
||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||
|
||||
FROM (
|
||||
SELECT oid, typname, typnamespace, typtype, typowner, (aclexplode(typacl)).* FROM pg_type
|
||||
SELECT oid, typname, typnamespace, typtype, typowner, (aclexplode(coalesce(typacl, acldefault('T', typowner)))).* FROM pg_type
|
||||
) AS t (oid, typname, typnamespace, typtype, typowner, grantor, grantee, prtype, grantable),
|
||||
pg_namespace n,
|
||||
pg_authid u_grantor,
|
||||
@ -2129,7 +2129,7 @@ CREATE VIEW usage_privileges AS
|
||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||
|
||||
FROM (
|
||||
SELECT oid, typname, typnamespace, typtype, typowner, (aclexplode(typacl)).* FROM pg_type
|
||||
SELECT oid, typname, typnamespace, typtype, typowner, (aclexplode(coalesce(typacl, acldefault('T', typowner)))).* FROM pg_type
|
||||
) AS t (oid, typname, typnamespace, typtype, typowner, grantor, grantee, prtype, grantable),
|
||||
pg_namespace n,
|
||||
pg_authid u_grantor,
|
||||
@ -2166,7 +2166,7 @@ CREATE VIEW usage_privileges AS
|
||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||
|
||||
FROM (
|
||||
SELECT fdwname, fdwowner, (aclexplode(fdwacl)).* FROM pg_foreign_data_wrapper
|
||||
SELECT fdwname, fdwowner, (aclexplode(coalesce(fdwacl, acldefault('F', fdwowner)))).* FROM pg_foreign_data_wrapper
|
||||
) AS fdw (fdwname, fdwowner, grantor, grantee, prtype, grantable),
|
||||
pg_authid u_grantor,
|
||||
(
|
||||
@ -2200,7 +2200,7 @@ CREATE VIEW usage_privileges AS
|
||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||
|
||||
FROM (
|
||||
SELECT srvname, srvowner, (aclexplode(srvacl)).* FROM pg_foreign_server
|
||||
SELECT srvname, srvowner, (aclexplode(coalesce(srvacl, acldefault('S', srvowner)))).* FROM pg_foreign_server
|
||||
) AS srv (srvname, srvowner, grantor, grantee, prtype, grantable),
|
||||
pg_authid u_grantor,
|
||||
(
|
||||
|
@ -834,6 +834,64 @@ acldefault(GrantObjectType objtype, Oid ownerId)
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* SQL-accessible version of acldefault(). Hackish mapping from "char" type to
|
||||
* ACL_OBJECT_* values, but it's only used in the information schema, not
|
||||
* documented for general use.
|
||||
*/
|
||||
Datum
|
||||
acldefault_sql(PG_FUNCTION_ARGS)
|
||||
{
|
||||
char objtypec = PG_GETARG_CHAR(0);
|
||||
Oid owner = PG_GETARG_OID(1);
|
||||
GrantObjectType objtype = 0;
|
||||
|
||||
switch (objtypec)
|
||||
{
|
||||
case 'c':
|
||||
objtype = ACL_OBJECT_COLUMN;
|
||||
break;
|
||||
case 'r':
|
||||
objtype = ACL_OBJECT_RELATION;
|
||||
break;
|
||||
case 's':
|
||||
objtype = ACL_OBJECT_SEQUENCE;
|
||||
break;
|
||||
case 'd':
|
||||
objtype = ACL_OBJECT_DATABASE;
|
||||
break;
|
||||
case 'f':
|
||||
objtype = ACL_OBJECT_FUNCTION;
|
||||
break;
|
||||
case 'l':
|
||||
objtype = ACL_OBJECT_LANGUAGE;
|
||||
break;
|
||||
case 'L':
|
||||
objtype = ACL_OBJECT_LARGEOBJECT;
|
||||
break;
|
||||
case 'n':
|
||||
objtype = ACL_OBJECT_NAMESPACE;
|
||||
break;
|
||||
case 't':
|
||||
objtype = ACL_OBJECT_TABLESPACE;
|
||||
break;
|
||||
case 'F':
|
||||
objtype = ACL_OBJECT_FDW;
|
||||
break;
|
||||
case 'S':
|
||||
objtype = ACL_OBJECT_FOREIGN_SERVER;
|
||||
break;
|
||||
case 'T':
|
||||
objtype = ACL_OBJECT_TYPE;
|
||||
break;
|
||||
default:
|
||||
elog(ERROR, "unrecognized objtype abbreviation: %c", objtypec);
|
||||
}
|
||||
|
||||
PG_RETURN_ACL_P(acldefault(objtype, owner));
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* Update an ACL array to add or remove specified privileges.
|
||||
*
|
||||
|
@ -53,6 +53,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 201201262
|
||||
#define CATALOG_VERSION_NO 201201271
|
||||
|
||||
#endif
|
||||
|
@ -1094,6 +1094,8 @@ DESCR("contains");
|
||||
DATA(insert OID = 1062 ( aclitemeq PGNSP PGUID 12 1 0 0 0 f f f t f i 2 0 16 "1033 1033" _null_ _null_ _null_ _null_ aclitem_eq _null_ _null_ _null_ ));
|
||||
DATA(insert OID = 1365 ( makeaclitem PGNSP PGUID 12 1 0 0 0 f f f t f i 4 0 1033 "26 26 25 16" _null_ _null_ _null_ _null_ makeaclitem _null_ _null_ _null_ ));
|
||||
DESCR("make ACL item");
|
||||
DATA(insert OID = 3943 ( acldefault PGNSP PGUID 12 1 0 0 0 f f f t f i 2 0 1034 "18 26" _null_ _null_ _null_ _null_ acldefault_sql _null_ _null_ _null_ ));
|
||||
DESCR("TODO");
|
||||
DATA(insert OID = 1689 ( aclexplode PGNSP PGUID 12 1 10 0 0 f f f t t s 1 0 2249 "1034" "{1034,26,26,25,16}" "{i,o,o,o,o}" "{acl,grantor,grantee,privilege_type,is_grantable}" _null_ aclexplode _null_ _null_ _null_ ));
|
||||
DESCR("convert ACL item array to table, for use by information schema");
|
||||
DATA(insert OID = 1044 ( bpcharin PGNSP PGUID 12 1 0 0 0 f f f t f i 3 0 1042 "2275 26 23" _null_ _null_ _null_ _null_ bpcharin _null_ _null_ _null_ ));
|
||||
|
@ -245,6 +245,7 @@ extern Datum aclcontains(PG_FUNCTION_ARGS);
|
||||
extern Datum makeaclitem(PG_FUNCTION_ARGS);
|
||||
extern Datum aclitem_eq(PG_FUNCTION_ARGS);
|
||||
extern Datum hash_aclitem(PG_FUNCTION_ARGS);
|
||||
extern Datum acldefault_sql(PG_FUNCTION_ARGS);
|
||||
extern Datum aclexplode(PG_FUNCTION_ARGS);
|
||||
|
||||
/*
|
||||
|
@ -896,7 +896,7 @@ SELECT * FROM information_schema.user_mapping_options ORDER BY lower(authorizati
|
||||
regress_test_role | regression | t1 | username | bob
|
||||
(7 rows)
|
||||
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
grantor | grantee | object_catalog | object_schema | object_name | object_type | privilege_type | is_grantable
|
||||
-------------------+-----------------------+----------------+---------------+-------------+----------------------+----------------+--------------
|
||||
foreign_data_user | foreign_data_user | regression | | foo | FOREIGN DATA WRAPPER | USAGE | YES
|
||||
@ -905,7 +905,7 @@ SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIG
|
||||
foreign_data_user | regress_test_role2 | regression | | s6 | FOREIGN SERVER | USAGE | YES
|
||||
(4 rows)
|
||||
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
grantor | grantee | object_catalog | object_schema | object_name | object_type | privilege_type | is_grantable
|
||||
-------------------+-----------------------+----------------+---------------+-------------+----------------------+----------------+--------------
|
||||
foreign_data_user | foreign_data_user | regression | | foo | FOREIGN DATA WRAPPER | USAGE | YES
|
||||
@ -939,14 +939,14 @@ SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
|
||||
regress_test_role | regression | t1 | username | bob
|
||||
(5 rows)
|
||||
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
grantor | grantee | object_catalog | object_schema | object_name | object_type | privilege_type | is_grantable
|
||||
-------------------+-----------------------+----------------+---------------+-------------+----------------------+----------------+--------------
|
||||
foreign_data_user | regress_test_indirect | regression | | foo | FOREIGN DATA WRAPPER | USAGE | NO
|
||||
foreign_data_user | regress_test_role2 | regression | | s6 | FOREIGN SERVER | USAGE | YES
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
grantor | grantee | object_catalog | object_schema | object_name | object_type | privilege_type | is_grantable
|
||||
-------------------+-----------------------+----------------+---------------+-------------+----------------------+----------------+--------------
|
||||
foreign_data_user | regress_test_indirect | regression | | foo | FOREIGN DATA WRAPPER | USAGE | NO
|
||||
|
@ -362,14 +362,14 @@ SELECT * FROM information_schema.foreign_servers ORDER BY 1, 2;
|
||||
SELECT * FROM information_schema.foreign_server_options ORDER BY 1, 2, 3;
|
||||
SELECT * FROM information_schema.user_mappings ORDER BY lower(authorization_identifier), 2, 3;
|
||||
SELECT * FROM information_schema.user_mapping_options ORDER BY lower(authorization_identifier), 2, 3, 4;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.foreign_tables ORDER BY 1, 2, 3;
|
||||
SELECT * FROM information_schema.foreign_table_options ORDER BY 1, 2, 3, 4;
|
||||
SET ROLE regress_test_role;
|
||||
SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' AND object_name IN ('s6', 'foo') ORDER BY 1, 2, 3, 4, 5;
|
||||
DROP USER MAPPING FOR current_user SERVER t1;
|
||||
SET ROLE regress_test_role2;
|
||||
SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
|
||||
|
Loading…
Reference in New Issue
Block a user