mirror of
https://github.com/postgres/postgres.git
synced 2025-04-29 13:56:47 +03:00
Speed up information schema privilege views
Instead of expensive cross joins to resolve the ACL, add table-returning function aclexplode() that expands the ACL into a useful form, and join against that. Also, implement the role_*_grants views as a thin layer over the respective *_privileges views instead of essentially repeating the same code twice. fixes bug #4596 by Joachim Wieland, with cleanup by me
This commit is contained in:
parent
636bac6e46
commit
36f887c41c
@ -4,7 +4,7 @@
|
|||||||
*
|
*
|
||||||
* Copyright (c) 2003-2009, PostgreSQL Global Development Group
|
* Copyright (c) 2003-2009, PostgreSQL Global Development Group
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/backend/catalog/information_schema.sql,v 1.58 2009/07/28 02:56:29 tgl Exp $
|
* $PostgreSQL: pgsql/src/backend/catalog/information_schema.sql,v 1.59 2009/12/05 21:43:35 petere Exp $
|
||||||
*/
|
*/
|
||||||
|
|
||||||
/*
|
/*
|
||||||
@ -483,42 +483,63 @@ CREATE VIEW column_privileges AS
|
|||||||
CAST(grantee.rolname AS sql_identifier) AS grantee,
|
CAST(grantee.rolname AS sql_identifier) AS grantee,
|
||||||
CAST(current_database() AS sql_identifier) AS table_catalog,
|
CAST(current_database() AS sql_identifier) AS table_catalog,
|
||||||
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
||||||
CAST(c.relname AS sql_identifier) AS table_name,
|
CAST(x.relname AS sql_identifier) AS table_name,
|
||||||
CAST(a.attname AS sql_identifier) AS column_name,
|
CAST(x.attname AS sql_identifier) AS column_name,
|
||||||
CAST(pr.type AS character_data) AS privilege_type,
|
CAST(x.prtype AS character_data) AS privilege_type,
|
||||||
CAST(
|
CAST(
|
||||||
CASE WHEN
|
CASE WHEN
|
||||||
-- object owner always has grant options
|
-- object owner always has grant options
|
||||||
pg_has_role(grantee.oid, c.relowner, 'USAGE')
|
pg_has_role(x.grantee, x.relowner, 'USAGE')
|
||||||
OR aclcontains(c.relacl,
|
OR x.grantable
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
OR aclcontains(a.attacl,
|
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||||
|
|
||||||
FROM pg_attribute a,
|
FROM (
|
||||||
pg_class c,
|
SELECT pr_c.grantor,
|
||||||
|
pr_c.grantee,
|
||||||
|
attname,
|
||||||
|
relname,
|
||||||
|
relnamespace,
|
||||||
|
pr_c.prtype,
|
||||||
|
pr_c.grantable,
|
||||||
|
pr_c.relowner
|
||||||
|
FROM (SELECT oid, relname, relnamespace, relowner, (aclexplode(relacl)).*
|
||||||
|
FROM pg_class
|
||||||
|
WHERE relkind IN ('r', 'v')
|
||||||
|
) pr_c (oid, relname, relnamespace, relowner, grantor, grantee, prtype, grantable),
|
||||||
|
pg_attribute a
|
||||||
|
WHERE a.attrelid = pr_c.oid
|
||||||
|
AND a.attnum > 0
|
||||||
|
AND NOT a.attisdropped
|
||||||
|
UNION
|
||||||
|
SELECT pr_a.grantor,
|
||||||
|
pr_a.grantee,
|
||||||
|
attname,
|
||||||
|
relname,
|
||||||
|
relnamespace,
|
||||||
|
pr_a.prtype,
|
||||||
|
pr_a.grantable,
|
||||||
|
c.relowner
|
||||||
|
FROM (SELECT attrelid, attname, (aclexplode(attacl)).*
|
||||||
|
FROM pg_attribute
|
||||||
|
WHERE attnum > 0
|
||||||
|
AND NOT attisdropped
|
||||||
|
) pr_a (attrelid, attname, grantor, grantee, prtype, grantable),
|
||||||
|
pg_class c
|
||||||
|
WHERE pr_a.attrelid = c.oid
|
||||||
|
AND relkind IN ('r','v')
|
||||||
|
) x,
|
||||||
pg_namespace nc,
|
pg_namespace nc,
|
||||||
pg_authid u_grantor,
|
pg_authid u_grantor,
|
||||||
(
|
(
|
||||||
SELECT oid, rolname FROM pg_authid
|
SELECT oid, rolname FROM pg_authid
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT 0::oid, 'PUBLIC'
|
SELECT 0::oid, 'PUBLIC'
|
||||||
) AS grantee (oid, rolname),
|
) AS grantee (oid, rolname)
|
||||||
(VALUES ('SELECT'),
|
|
||||||
('INSERT'),
|
|
||||||
('UPDATE'),
|
|
||||||
('REFERENCES')) AS pr (type)
|
|
||||||
|
|
||||||
WHERE a.attrelid = c.oid
|
WHERE x.relnamespace = nc.oid
|
||||||
AND c.relnamespace = nc.oid
|
AND x.grantee = grantee.oid
|
||||||
AND a.attnum > 0
|
AND x.grantor = u_grantor.oid
|
||||||
AND NOT a.attisdropped
|
AND x.prtype IN ('INSERT', 'SELECT', 'UPDATE', 'REFERENCES')
|
||||||
AND c.relkind IN ('r', 'v')
|
|
||||||
AND (aclcontains(c.relacl,
|
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, false))
|
|
||||||
OR aclcontains(a.attacl,
|
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, false)))
|
|
||||||
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
||||||
OR pg_has_role(grantee.oid, 'USAGE')
|
OR pg_has_role(grantee.oid, 'USAGE')
|
||||||
OR grantee.rolname = 'PUBLIC');
|
OR grantee.rolname = 'PUBLIC');
|
||||||
@ -1124,126 +1145,25 @@ GRANT SELECT ON referential_constraints TO PUBLIC;
|
|||||||
*/
|
*/
|
||||||
|
|
||||||
CREATE VIEW role_column_grants AS
|
CREATE VIEW role_column_grants AS
|
||||||
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
|
SELECT grantor,
|
||||||
CAST(g_grantee.rolname AS sql_identifier) AS grantee,
|
grantee,
|
||||||
CAST(current_database() AS sql_identifier) AS table_catalog,
|
table_catalog,
|
||||||
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
table_schema,
|
||||||
CAST(c.relname AS sql_identifier) AS table_name,
|
table_name,
|
||||||
CAST(a.attname AS sql_identifier) AS column_name,
|
column_name,
|
||||||
CAST(pr.type AS character_data) AS privilege_type,
|
privilege_type,
|
||||||
CAST(
|
is_grantable
|
||||||
CASE WHEN
|
FROM column_privileges
|
||||||
-- object owner always has grant options
|
WHERE grantor IN (SELECT role_name FROM enabled_roles)
|
||||||
pg_has_role(g_grantee.oid, c.relowner, 'USAGE')
|
OR grantee IN (SELECT role_name FROM enabled_roles);
|
||||||
OR aclcontains(c.relacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
OR aclcontains(a.attacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
|
||||||
|
|
||||||
FROM pg_attribute a,
|
|
||||||
pg_class c,
|
|
||||||
pg_namespace nc,
|
|
||||||
pg_authid u_grantor,
|
|
||||||
pg_authid g_grantee,
|
|
||||||
(VALUES ('SELECT'),
|
|
||||||
('INSERT'),
|
|
||||||
('UPDATE'),
|
|
||||||
('REFERENCES')) AS pr (type)
|
|
||||||
|
|
||||||
WHERE a.attrelid = c.oid
|
|
||||||
AND c.relnamespace = nc.oid
|
|
||||||
AND a.attnum > 0
|
|
||||||
AND NOT a.attisdropped
|
|
||||||
AND c.relkind IN ('r', 'v')
|
|
||||||
AND (aclcontains(c.relacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, false))
|
|
||||||
OR aclcontains(a.attacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, false)))
|
|
||||||
AND (u_grantor.rolname IN (SELECT role_name FROM enabled_roles)
|
|
||||||
OR g_grantee.rolname IN (SELECT role_name FROM enabled_roles));
|
|
||||||
|
|
||||||
GRANT SELECT ON role_column_grants TO PUBLIC;
|
GRANT SELECT ON role_column_grants TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
/*
|
-- 5.39 ROLE_ROUTINE_GRANTS view is based on 5.45 ROUTINE_PRIVILEGES and is defined there instead.
|
||||||
* 5.39
|
|
||||||
* ROLE_ROUTINE_GRANTS view
|
|
||||||
*/
|
|
||||||
|
|
||||||
CREATE VIEW role_routine_grants AS
|
|
||||||
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
|
|
||||||
CAST(g_grantee.rolname AS sql_identifier) AS grantee,
|
|
||||||
CAST(current_database() AS sql_identifier) AS specific_catalog,
|
|
||||||
CAST(n.nspname AS sql_identifier) AS specific_schema,
|
|
||||||
CAST(p.proname || '_' || CAST(p.oid AS text) AS sql_identifier) AS specific_name,
|
|
||||||
CAST(current_database() AS sql_identifier) AS routine_catalog,
|
|
||||||
CAST(n.nspname AS sql_identifier) AS routine_schema,
|
|
||||||
CAST(p.proname AS sql_identifier) AS routine_name,
|
|
||||||
CAST('EXECUTE' AS character_data) AS privilege_type,
|
|
||||||
CAST(
|
|
||||||
CASE WHEN
|
|
||||||
-- object owner always has grant options
|
|
||||||
pg_has_role(g_grantee.oid, p.proowner, 'USAGE')
|
|
||||||
OR aclcontains(p.proacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'EXECUTE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
|
||||||
|
|
||||||
FROM pg_proc p,
|
|
||||||
pg_namespace n,
|
|
||||||
pg_authid u_grantor,
|
|
||||||
pg_authid g_grantee
|
|
||||||
|
|
||||||
WHERE p.pronamespace = n.oid
|
|
||||||
AND aclcontains(p.proacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'EXECUTE', false))
|
|
||||||
AND (u_grantor.rolname IN (SELECT role_name FROM enabled_roles)
|
|
||||||
OR g_grantee.rolname IN (SELECT role_name FROM enabled_roles));
|
|
||||||
|
|
||||||
GRANT SELECT ON role_routine_grants TO PUBLIC;
|
|
||||||
|
|
||||||
|
|
||||||
/*
|
-- 5.40 ROLE_TABLE_GRANTS view is based on 5.60 TABLE_PRIVILEGES and is defined there instead.
|
||||||
* 5.40
|
|
||||||
* ROLE_TABLE_GRANTS view
|
|
||||||
*/
|
|
||||||
|
|
||||||
CREATE VIEW role_table_grants AS
|
|
||||||
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
|
|
||||||
CAST(g_grantee.rolname AS sql_identifier) AS grantee,
|
|
||||||
CAST(current_database() AS sql_identifier) AS table_catalog,
|
|
||||||
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
|
||||||
CAST(c.relname AS sql_identifier) AS table_name,
|
|
||||||
CAST(pr.type AS character_data) AS privilege_type,
|
|
||||||
CAST(
|
|
||||||
CASE WHEN
|
|
||||||
-- object owner always has grant options
|
|
||||||
pg_has_role(g_grantee.oid, c.relowner, 'USAGE')
|
|
||||||
OR aclcontains(c.relacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable,
|
|
||||||
CAST('NO' AS yes_or_no) AS with_hierarchy
|
|
||||||
|
|
||||||
FROM pg_class c,
|
|
||||||
pg_namespace nc,
|
|
||||||
pg_authid u_grantor,
|
|
||||||
pg_authid g_grantee,
|
|
||||||
(VALUES ('SELECT'),
|
|
||||||
('INSERT'),
|
|
||||||
('UPDATE'),
|
|
||||||
('DELETE'),
|
|
||||||
('TRUNCATE'),
|
|
||||||
('REFERENCES'),
|
|
||||||
('TRIGGER')) AS pr (type)
|
|
||||||
|
|
||||||
WHERE c.relnamespace = nc.oid
|
|
||||||
AND c.relkind IN ('r', 'v')
|
|
||||||
AND aclcontains(c.relacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, pr.type, false))
|
|
||||||
AND (u_grantor.rolname IN (SELECT role_name FROM enabled_roles)
|
|
||||||
OR g_grantee.rolname IN (SELECT role_name FROM enabled_roles));
|
|
||||||
|
|
||||||
GRANT SELECT ON role_table_grants TO PUBLIC;
|
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
@ -1254,66 +1174,8 @@ GRANT SELECT ON role_table_grants TO PUBLIC;
|
|||||||
-- feature not supported
|
-- feature not supported
|
||||||
|
|
||||||
|
|
||||||
/*
|
|
||||||
* 5.42
|
|
||||||
* ROLE_USAGE_GRANTS view
|
|
||||||
*/
|
|
||||||
|
|
||||||
CREATE VIEW role_usage_grants AS
|
-- 5.42 ROLE_USAGE_GRANTS view is based on 5.71 USAGE_PRIVILEGES and is defined there instead.
|
||||||
|
|
||||||
/* foreign-data wrappers */
|
|
||||||
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
|
|
||||||
CAST(g_grantee.rolname AS sql_identifier) AS grantee,
|
|
||||||
CAST(current_database() AS sql_identifier) AS object_catalog,
|
|
||||||
CAST('' AS sql_identifier) AS object_schema,
|
|
||||||
CAST(fdw.fdwname AS sql_identifier) AS object_name,
|
|
||||||
CAST('FOREIGN DATA WRAPPER' AS character_data) AS object_type,
|
|
||||||
CAST('USAGE' AS character_data) AS privilege_type,
|
|
||||||
CAST(
|
|
||||||
CASE WHEN
|
|
||||||
-- object owner always has grant options
|
|
||||||
pg_has_role(g_grantee.oid, fdw.fdwowner, 'USAGE')
|
|
||||||
OR aclcontains(fdw.fdwacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'USAGE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
|
||||||
|
|
||||||
FROM pg_foreign_data_wrapper fdw,
|
|
||||||
pg_authid u_grantor,
|
|
||||||
pg_authid g_grantee
|
|
||||||
|
|
||||||
WHERE aclcontains(fdw.fdwacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'USAGE', false))
|
|
||||||
AND (u_grantor.rolname IN (SELECT role_name FROM enabled_roles)
|
|
||||||
OR g_grantee.rolname IN (SELECT role_name FROM enabled_roles))
|
|
||||||
|
|
||||||
UNION ALL
|
|
||||||
|
|
||||||
/* foreign server */
|
|
||||||
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
|
|
||||||
CAST(g_grantee.rolname AS sql_identifier) AS grantee,
|
|
||||||
CAST(current_database() AS sql_identifier) AS object_catalog,
|
|
||||||
CAST('' AS sql_identifier) AS object_schema,
|
|
||||||
CAST(srv.srvname AS sql_identifier) AS object_name,
|
|
||||||
CAST('FOREIGN SERVER' AS character_data) AS object_type,
|
|
||||||
CAST('USAGE' AS character_data) AS privilege_type,
|
|
||||||
CAST(
|
|
||||||
CASE WHEN
|
|
||||||
-- object owner always has grant options
|
|
||||||
pg_has_role(g_grantee.oid, srv.srvowner, 'USAGE')
|
|
||||||
OR aclcontains(srv.srvacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'USAGE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
|
||||||
|
|
||||||
FROM pg_foreign_server srv,
|
|
||||||
pg_authid u_grantor,
|
|
||||||
pg_authid g_grantee
|
|
||||||
|
|
||||||
WHERE aclcontains(srv.srvacl,
|
|
||||||
makeaclitem(g_grantee.oid, u_grantor.oid, 'USAGE', false))
|
|
||||||
AND (u_grantor.rolname IN (SELECT role_name FROM enabled_roles)
|
|
||||||
OR g_grantee.rolname IN (SELECT role_name FROM enabled_roles));
|
|
||||||
|
|
||||||
GRANT SELECT ON role_usage_grants TO PUBLIC;
|
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
@ -1351,11 +1213,12 @@ CREATE VIEW routine_privileges AS
|
|||||||
CASE WHEN
|
CASE WHEN
|
||||||
-- object owner always has grant options
|
-- object owner always has grant options
|
||||||
pg_has_role(grantee.oid, p.proowner, 'USAGE')
|
pg_has_role(grantee.oid, p.proowner, 'USAGE')
|
||||||
OR aclcontains(p.proacl,
|
OR p.grantable
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'EXECUTE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||||
|
|
||||||
FROM pg_proc p,
|
FROM (
|
||||||
|
SELECT oid, proname, proowner, pronamespace, (aclexplode(proacl)).* FROM pg_proc
|
||||||
|
) p (oid, proname, proowner, pronamespace, grantor, grantee, prtype, grantable),
|
||||||
pg_namespace n,
|
pg_namespace n,
|
||||||
pg_authid u_grantor,
|
pg_authid u_grantor,
|
||||||
(
|
(
|
||||||
@ -1365,8 +1228,9 @@ CREATE VIEW routine_privileges AS
|
|||||||
) AS grantee (oid, rolname)
|
) AS grantee (oid, rolname)
|
||||||
|
|
||||||
WHERE p.pronamespace = n.oid
|
WHERE p.pronamespace = n.oid
|
||||||
AND aclcontains(p.proacl,
|
AND grantee.oid = p.grantee
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'EXECUTE', false))
|
AND u_grantor.oid = p.grantor
|
||||||
|
AND p.prtype IN ('EXECUTE')
|
||||||
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
||||||
OR pg_has_role(grantee.oid, 'USAGE')
|
OR pg_has_role(grantee.oid, 'USAGE')
|
||||||
OR grantee.rolname = 'PUBLIC');
|
OR grantee.rolname = 'PUBLIC');
|
||||||
@ -1374,6 +1238,29 @@ CREATE VIEW routine_privileges AS
|
|||||||
GRANT SELECT ON routine_privileges TO PUBLIC;
|
GRANT SELECT ON routine_privileges TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* 5.39
|
||||||
|
* ROLE_ROUTINE_GRANTS view
|
||||||
|
*/
|
||||||
|
|
||||||
|
CREATE VIEW role_routine_grants AS
|
||||||
|
SELECT grantor,
|
||||||
|
grantee,
|
||||||
|
specific_catalog,
|
||||||
|
specific_schema,
|
||||||
|
specific_name,
|
||||||
|
routine_catalog,
|
||||||
|
routine_schema,
|
||||||
|
routine_name,
|
||||||
|
privilege_type,
|
||||||
|
is_grantable
|
||||||
|
FROM routine_privileges
|
||||||
|
WHERE grantor IN (SELECT role_name FROM enabled_roles)
|
||||||
|
OR grantee IN (SELECT role_name FROM enabled_roles);
|
||||||
|
|
||||||
|
GRANT SELECT ON role_routine_grants TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* 5.46
|
* 5.46
|
||||||
* ROUTINE_ROUTINE_USAGE view
|
* ROUTINE_ROUTINE_USAGE view
|
||||||
@ -1838,36 +1725,31 @@ CREATE VIEW table_privileges AS
|
|||||||
CAST(current_database() AS sql_identifier) AS table_catalog,
|
CAST(current_database() AS sql_identifier) AS table_catalog,
|
||||||
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
CAST(nc.nspname AS sql_identifier) AS table_schema,
|
||||||
CAST(c.relname AS sql_identifier) AS table_name,
|
CAST(c.relname AS sql_identifier) AS table_name,
|
||||||
CAST(pr.type AS character_data) AS privilege_type,
|
CAST(c.prtype AS character_data) AS privilege_type,
|
||||||
CAST(
|
CAST(
|
||||||
CASE WHEN
|
CASE WHEN
|
||||||
-- object owner always has grant options
|
-- object owner always has grant options
|
||||||
pg_has_role(grantee.oid, c.relowner, 'USAGE')
|
pg_has_role(grantee.oid, c.relowner, 'USAGE')
|
||||||
OR aclcontains(c.relacl,
|
OR c.grantable
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable,
|
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable,
|
||||||
CAST('NO' AS yes_or_no) AS with_hierarchy
|
CAST('NO' AS yes_or_no) AS with_hierarchy
|
||||||
|
|
||||||
FROM pg_class c,
|
FROM (
|
||||||
|
SELECT oid, relname, relnamespace, relkind, relowner, (aclexplode(relacl)).* FROM pg_class
|
||||||
|
) AS c (oid, relname, relnamespace, relkind, relowner, grantor, grantee, prtype, grantable),
|
||||||
pg_namespace nc,
|
pg_namespace nc,
|
||||||
pg_authid u_grantor,
|
pg_authid u_grantor,
|
||||||
(
|
(
|
||||||
SELECT oid, rolname FROM pg_authid
|
SELECT oid, rolname FROM pg_authid
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT 0::oid, 'PUBLIC'
|
SELECT 0::oid, 'PUBLIC'
|
||||||
) AS grantee (oid, rolname),
|
) AS grantee (oid, rolname)
|
||||||
(VALUES ('SELECT'),
|
|
||||||
('INSERT'),
|
|
||||||
('UPDATE'),
|
|
||||||
('DELETE'),
|
|
||||||
('TRUNCATE'),
|
|
||||||
('REFERENCES'),
|
|
||||||
('TRIGGER')) AS pr (type)
|
|
||||||
|
|
||||||
WHERE c.relnamespace = nc.oid
|
WHERE c.relnamespace = nc.oid
|
||||||
AND c.relkind IN ('r', 'v')
|
AND c.relkind IN ('r', 'v')
|
||||||
AND aclcontains(c.relacl,
|
AND c.grantee = grantee.oid
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, pr.type, false))
|
AND c.grantor = u_grantor.oid
|
||||||
|
AND c.prtype IN ('INSERT', 'SELECT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER')
|
||||||
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
||||||
OR pg_has_role(grantee.oid, 'USAGE')
|
OR pg_has_role(grantee.oid, 'USAGE')
|
||||||
OR grantee.rolname = 'PUBLIC');
|
OR grantee.rolname = 'PUBLIC');
|
||||||
@ -1875,6 +1757,27 @@ CREATE VIEW table_privileges AS
|
|||||||
GRANT SELECT ON table_privileges TO PUBLIC;
|
GRANT SELECT ON table_privileges TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* 5.40
|
||||||
|
* ROLE_TABLE_GRANTS view
|
||||||
|
*/
|
||||||
|
|
||||||
|
CREATE VIEW role_table_grants AS
|
||||||
|
SELECT grantor,
|
||||||
|
grantee,
|
||||||
|
table_catalog,
|
||||||
|
table_schema,
|
||||||
|
table_name,
|
||||||
|
privilege_type,
|
||||||
|
is_grantable,
|
||||||
|
with_hierarchy
|
||||||
|
FROM table_privileges
|
||||||
|
WHERE grantor IN (SELECT role_name FROM enabled_roles)
|
||||||
|
OR grantee IN (SELECT role_name FROM enabled_roles);
|
||||||
|
|
||||||
|
GRANT SELECT ON role_table_grants TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* 5.61
|
* 5.61
|
||||||
* TABLES view
|
* TABLES view
|
||||||
@ -2088,11 +1991,12 @@ CREATE VIEW usage_privileges AS
|
|||||||
CASE WHEN
|
CASE WHEN
|
||||||
-- object owner always has grant options
|
-- object owner always has grant options
|
||||||
pg_has_role(grantee.oid, fdw.fdwowner, 'USAGE')
|
pg_has_role(grantee.oid, fdw.fdwowner, 'USAGE')
|
||||||
OR aclcontains(fdw.fdwacl,
|
OR fdw.grantable
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'USAGE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||||
|
|
||||||
FROM pg_foreign_data_wrapper fdw,
|
FROM (
|
||||||
|
SELECT fdwname, fdwowner, (aclexplode(fdwacl)).* FROM pg_foreign_data_wrapper
|
||||||
|
) AS fdw (fdwname, fdwowner, grantor, grantee, prtype, grantable),
|
||||||
pg_authid u_grantor,
|
pg_authid u_grantor,
|
||||||
(
|
(
|
||||||
SELECT oid, rolname FROM pg_authid
|
SELECT oid, rolname FROM pg_authid
|
||||||
@ -2100,8 +2004,9 @@ CREATE VIEW usage_privileges AS
|
|||||||
SELECT 0::oid, 'PUBLIC'
|
SELECT 0::oid, 'PUBLIC'
|
||||||
) AS grantee (oid, rolname)
|
) AS grantee (oid, rolname)
|
||||||
|
|
||||||
WHERE aclcontains(fdw.fdwacl,
|
WHERE u_grantor.oid = fdw.grantor
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'USAGE', false))
|
AND grantee.oid = fdw.grantee
|
||||||
|
AND fdw.prtype IN ('USAGE')
|
||||||
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
||||||
OR pg_has_role(grantee.oid, 'USAGE')
|
OR pg_has_role(grantee.oid, 'USAGE')
|
||||||
OR grantee.rolname = 'PUBLIC')
|
OR grantee.rolname = 'PUBLIC')
|
||||||
@ -2120,11 +2025,12 @@ CREATE VIEW usage_privileges AS
|
|||||||
CASE WHEN
|
CASE WHEN
|
||||||
-- object owner always has grant options
|
-- object owner always has grant options
|
||||||
pg_has_role(grantee.oid, srv.srvowner, 'USAGE')
|
pg_has_role(grantee.oid, srv.srvowner, 'USAGE')
|
||||||
OR aclcontains(srv.srvacl,
|
OR srv.grantable
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'USAGE', true))
|
|
||||||
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable
|
||||||
|
|
||||||
FROM pg_foreign_server srv,
|
FROM (
|
||||||
|
SELECT srvname, srvowner, (aclexplode(srvacl)).* FROM pg_foreign_server
|
||||||
|
) AS srv (srvname, srvowner, grantor, grantee, prtype, grantable),
|
||||||
pg_authid u_grantor,
|
pg_authid u_grantor,
|
||||||
(
|
(
|
||||||
SELECT oid, rolname FROM pg_authid
|
SELECT oid, rolname FROM pg_authid
|
||||||
@ -2132,8 +2038,9 @@ CREATE VIEW usage_privileges AS
|
|||||||
SELECT 0::oid, 'PUBLIC'
|
SELECT 0::oid, 'PUBLIC'
|
||||||
) AS grantee (oid, rolname)
|
) AS grantee (oid, rolname)
|
||||||
|
|
||||||
WHERE aclcontains(srv.srvacl,
|
WHERE u_grantor.oid = srv.grantor
|
||||||
makeaclitem(grantee.oid, u_grantor.oid, 'USAGE', false))
|
AND grantee.oid = srv.grantee
|
||||||
|
AND srv.prtype IN ('USAGE')
|
||||||
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
AND (pg_has_role(u_grantor.oid, 'USAGE')
|
||||||
OR pg_has_role(grantee.oid, 'USAGE')
|
OR pg_has_role(grantee.oid, 'USAGE')
|
||||||
OR grantee.rolname = 'PUBLIC');
|
OR grantee.rolname = 'PUBLIC');
|
||||||
@ -2141,6 +2048,27 @@ CREATE VIEW usage_privileges AS
|
|||||||
GRANT SELECT ON usage_privileges TO PUBLIC;
|
GRANT SELECT ON usage_privileges TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* 5.42
|
||||||
|
* ROLE_USAGE_GRANTS view
|
||||||
|
*/
|
||||||
|
|
||||||
|
CREATE VIEW role_usage_grants AS
|
||||||
|
SELECT grantor,
|
||||||
|
grantee,
|
||||||
|
object_catalog,
|
||||||
|
object_schema,
|
||||||
|
object_name,
|
||||||
|
object_type,
|
||||||
|
privilege_type,
|
||||||
|
is_grantable
|
||||||
|
FROM usage_privileges
|
||||||
|
WHERE grantor IN (SELECT role_name FROM enabled_roles)
|
||||||
|
OR grantee IN (SELECT role_name FROM enabled_roles);
|
||||||
|
|
||||||
|
GRANT SELECT ON role_usage_grants TO PUBLIC;
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* 5.72
|
* 5.72
|
||||||
* USER_DEFINED_TYPES view
|
* USER_DEFINED_TYPES view
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/backend/utils/adt/acl.c,v 1.150 2009/10/05 19:24:41 tgl Exp $
|
* $PostgreSQL: pgsql/src/backend/utils/adt/acl.c,v 1.151 2009/12/05 21:43:35 petere Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -24,6 +24,7 @@
|
|||||||
#include "commands/dbcommands.h"
|
#include "commands/dbcommands.h"
|
||||||
#include "commands/tablespace.h"
|
#include "commands/tablespace.h"
|
||||||
#include "foreign/foreign.h"
|
#include "foreign/foreign.h"
|
||||||
|
#include "funcapi.h"
|
||||||
#include "miscadmin.h"
|
#include "miscadmin.h"
|
||||||
#include "utils/acl.h"
|
#include "utils/acl.h"
|
||||||
#include "utils/builtins.h"
|
#include "utils/builtins.h"
|
||||||
@ -1622,6 +1623,143 @@ convert_any_priv_string(text *priv_type_text,
|
|||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
static const char *
|
||||||
|
convert_aclright_to_string(int aclright)
|
||||||
|
{
|
||||||
|
switch (aclright)
|
||||||
|
{
|
||||||
|
case ACL_INSERT:
|
||||||
|
return "INSERT";
|
||||||
|
case ACL_SELECT:
|
||||||
|
return "SELECT";
|
||||||
|
case ACL_UPDATE:
|
||||||
|
return "UPDATE";
|
||||||
|
case ACL_DELETE:
|
||||||
|
return "DELETE";
|
||||||
|
case ACL_TRUNCATE:
|
||||||
|
return "TRUNCATE";
|
||||||
|
case ACL_REFERENCES:
|
||||||
|
return "REFERENCES";
|
||||||
|
case ACL_TRIGGER:
|
||||||
|
return "TRIGGER";
|
||||||
|
case ACL_EXECUTE:
|
||||||
|
return "EXECUTE";
|
||||||
|
case ACL_USAGE:
|
||||||
|
return "USAGE";
|
||||||
|
case ACL_CREATE:
|
||||||
|
return "CREATE";
|
||||||
|
case ACL_CREATE_TEMP:
|
||||||
|
return "TEMPORARY";
|
||||||
|
case ACL_CONNECT:
|
||||||
|
return "CONNECT";
|
||||||
|
default:
|
||||||
|
elog(ERROR, "unrecognized aclright: %d", aclright);
|
||||||
|
return NULL;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
|
/*----------
|
||||||
|
* Convert an aclitem[] to a table.
|
||||||
|
*
|
||||||
|
* Example:
|
||||||
|
*
|
||||||
|
* aclexplode('{=r/joe,foo=a*w/joe}'::aclitem[])
|
||||||
|
*
|
||||||
|
* returns the table
|
||||||
|
*
|
||||||
|
* {{ OID(joe), 0::OID, 'SELECT', false },
|
||||||
|
* { OID(joe), OID(foo), 'INSERT', true },
|
||||||
|
* { OID(joe), OID(foo), 'UPDATE', false }}
|
||||||
|
*----------
|
||||||
|
*/
|
||||||
|
Datum
|
||||||
|
aclexplode(PG_FUNCTION_ARGS)
|
||||||
|
{
|
||||||
|
FuncCallContext *funcctx;
|
||||||
|
int *idx;
|
||||||
|
Acl *acl = PG_GETARG_ACL_P(0);
|
||||||
|
AclItem *aidat;
|
||||||
|
|
||||||
|
if (SRF_IS_FIRSTCALL())
|
||||||
|
{
|
||||||
|
TupleDesc tupdesc;
|
||||||
|
MemoryContext oldcontext;
|
||||||
|
|
||||||
|
check_acl(acl);
|
||||||
|
|
||||||
|
funcctx = SRF_FIRSTCALL_INIT();
|
||||||
|
oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
|
||||||
|
|
||||||
|
/*
|
||||||
|
* build tupdesc for result tuples (matches out parameters in
|
||||||
|
* pg_proc entry)
|
||||||
|
*/
|
||||||
|
tupdesc = CreateTemplateTupleDesc(4, false);
|
||||||
|
TupleDescInitEntry(tupdesc, (AttrNumber) 1, "grantor",
|
||||||
|
OIDOID, -1, 0);
|
||||||
|
TupleDescInitEntry(tupdesc, (AttrNumber) 2, "grantee",
|
||||||
|
OIDOID, -1, 0);
|
||||||
|
TupleDescInitEntry(tupdesc, (AttrNumber) 3, "privilege_type",
|
||||||
|
TEXTOID, -1, 0);
|
||||||
|
TupleDescInitEntry(tupdesc, (AttrNumber) 4, "is_grantable",
|
||||||
|
BOOLOID, -1, 0);
|
||||||
|
|
||||||
|
funcctx->tuple_desc = BlessTupleDesc(tupdesc);
|
||||||
|
|
||||||
|
/* allocate memory for user context */
|
||||||
|
idx = (int *) palloc(sizeof(int[2]));
|
||||||
|
idx[0] = 0; /* ACL array item index */
|
||||||
|
idx[1] = -1; /* privilege type counter */
|
||||||
|
funcctx->user_fctx = (void *) idx;
|
||||||
|
|
||||||
|
MemoryContextSwitchTo(oldcontext);
|
||||||
|
}
|
||||||
|
|
||||||
|
funcctx = SRF_PERCALL_SETUP();
|
||||||
|
idx = (int *) funcctx->user_fctx;
|
||||||
|
|
||||||
|
aidat = ACL_DAT(acl);
|
||||||
|
while (1)
|
||||||
|
{
|
||||||
|
idx[1]++;
|
||||||
|
if (idx[1] == N_ACL_RIGHTS)
|
||||||
|
{
|
||||||
|
idx[1] = 0;
|
||||||
|
idx[0]++;
|
||||||
|
if (idx[0] == ACL_NUM(acl))
|
||||||
|
/* done */
|
||||||
|
break;
|
||||||
|
}
|
||||||
|
|
||||||
|
Assert(idx[0] < ACL_NUM(acl));
|
||||||
|
Assert(idx[1] < N_ACL_RIGHTS);
|
||||||
|
|
||||||
|
if (ACLITEM_GET_PRIVS(aidat[idx[0]]) & (1 << idx[1]))
|
||||||
|
{
|
||||||
|
Datum result;
|
||||||
|
Datum values[4];
|
||||||
|
bool nulls[4];
|
||||||
|
HeapTuple tuple;
|
||||||
|
|
||||||
|
values[0] = ObjectIdGetDatum(aidat[idx[0]].ai_grantor);
|
||||||
|
values[1] = ObjectIdGetDatum(aidat[idx[0]].ai_grantee);
|
||||||
|
values[2] = CStringGetTextDatum(convert_aclright_to_string(1 << idx[1]));
|
||||||
|
values[3] = BoolGetDatum(ACLITEM_GET_GOPTIONS(aidat[idx[0]]) & (1 << idx[1]));
|
||||||
|
|
||||||
|
MemSet(nulls, 0, sizeof(nulls));
|
||||||
|
|
||||||
|
tuple = heap_form_tuple(funcctx->tuple_desc, values, nulls);
|
||||||
|
result = HeapTupleGetDatum(tuple);
|
||||||
|
|
||||||
|
SRF_RETURN_NEXT(funcctx, result);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
SRF_RETURN_DONE(funcctx);
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* has_table_privilege variants
|
* has_table_privilege variants
|
||||||
* These are all named "has_table_privilege" at the SQL level.
|
* These are all named "has_table_privilege" at the SQL level.
|
||||||
|
@ -37,7 +37,7 @@
|
|||||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||||
* Portions Copyright (c) 1994, Regents of the University of California
|
* Portions Copyright (c) 1994, Regents of the University of California
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.554 2009/11/29 18:14:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.555 2009/12/05 21:43:35 petere Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -53,6 +53,6 @@
|
|||||||
*/
|
*/
|
||||||
|
|
||||||
/* yyyymmddN */
|
/* yyyymmddN */
|
||||||
#define CATALOG_VERSION_NO 200911291
|
#define CATALOG_VERSION_NO 200912051
|
||||||
|
|
||||||
#endif
|
#endif
|
||||||
|
@ -7,7 +7,7 @@
|
|||||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||||
* Portions Copyright (c) 1994, Regents of the University of California
|
* Portions Copyright (c) 1994, Regents of the University of California
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.554 2009/11/29 18:14:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.555 2009/12/05 21:43:35 petere Exp $
|
||||||
*
|
*
|
||||||
* NOTES
|
* NOTES
|
||||||
* The script catalog/genbki.sh reads this file and generates .bki
|
* The script catalog/genbki.sh reads this file and generates .bki
|
||||||
@ -1314,6 +1314,8 @@ DATA(insert OID = 1062 ( aclitemeq PGNSP PGUID 12 1 0 0 f f f t f i 2 0 16
|
|||||||
DESCR("equality operator for ACL items");
|
DESCR("equality operator for ACL items");
|
||||||
DATA(insert OID = 1365 ( makeaclitem PGNSP PGUID 12 1 0 0 f f f t f i 4 0 1033 "26 26 25 16" _null_ _null_ _null_ _null_ makeaclitem _null_ _null_ _null_ ));
|
DATA(insert OID = 1365 ( makeaclitem PGNSP PGUID 12 1 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");
|
DESCR("make ACL item");
|
||||||
|
DATA(insert OID = 1248 ( aclexplode PGNSP PGUID 12 1 10 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 f f f t f i 3 0 1042 "2275 26 23" _null_ _null_ _null_ _null_ bpcharin _null_ _null_ _null_ ));
|
DATA(insert OID = 1044 ( bpcharin PGNSP PGUID 12 1 0 0 f f f t f i 3 0 1042 "2275 26 23" _null_ _null_ _null_ _null_ bpcharin _null_ _null_ _null_ ));
|
||||||
DESCR("I/O");
|
DESCR("I/O");
|
||||||
DATA(insert OID = 1045 ( bpcharout PGNSP PGUID 12 1 0 0 f f f t f i 1 0 2275 "1042" _null_ _null_ _null_ _null_ bpcharout _null_ _null_ _null_ ));
|
DATA(insert OID = 1045 ( bpcharout PGNSP PGUID 12 1 0 0 f f f t f i 1 0 2275 "1042" _null_ _null_ _null_ _null_ bpcharout _null_ _null_ _null_ ));
|
||||||
|
@ -7,7 +7,7 @@
|
|||||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||||
* Portions Copyright (c) 1994, Regents of the University of California
|
* Portions Copyright (c) 1994, Regents of the University of California
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/include/utils/acl.h,v 1.109 2009/10/05 19:24:49 tgl Exp $
|
* $PostgreSQL: pgsql/src/include/utils/acl.h,v 1.110 2009/12/05 21:43:36 petere Exp $
|
||||||
*
|
*
|
||||||
* NOTES
|
* NOTES
|
||||||
* An ACL array is simply an array of AclItems, representing the union
|
* An ACL array is simply an array of AclItems, representing the union
|
||||||
@ -238,6 +238,7 @@ extern Datum aclcontains(PG_FUNCTION_ARGS);
|
|||||||
extern Datum makeaclitem(PG_FUNCTION_ARGS);
|
extern Datum makeaclitem(PG_FUNCTION_ARGS);
|
||||||
extern Datum aclitem_eq(PG_FUNCTION_ARGS);
|
extern Datum aclitem_eq(PG_FUNCTION_ARGS);
|
||||||
extern Datum hash_aclitem(PG_FUNCTION_ARGS);
|
extern Datum hash_aclitem(PG_FUNCTION_ARGS);
|
||||||
|
extern Datum aclexplode(PG_FUNCTION_ARGS);
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* prototypes for functions in aclchk.c
|
* prototypes for functions in aclchk.c
|
||||||
|
Loading…
x
Reference in New Issue
Block a user