Skip to content

Commit

Permalink
Merge pull request #15 from rvkulikov/feature-13
Browse files Browse the repository at this point in the history
fix(Grants): fixed PUBLIC and "PUBLIC" role grants
  • Loading branch information
rvkulikov authored Feb 15, 2023
2 parents 692507b + 6ee813b commit 1ac47cb
Show file tree
Hide file tree
Showing 3 changed files with 267 additions and 9 deletions.
33 changes: 28 additions & 5 deletions .idea/workspace.xml

Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.

176 changes: 172 additions & 4 deletions ddl.sql
Original file line number Diff line number Diff line change
Expand Up @@ -73,6 +73,166 @@ begin
);



-- very important thing which property handles "PUBLIC", not PUBLIC role. They are not the same
create temporary view _role_table_grants(grantor, grantor_id, grantee, grantee_id, table_catalog, table_schema, table_name, privilege_type, is_grantable, with_hierarchy) as
with
_table_table_privileges as (
SELECT
u_grantor.oid AS grantor_id, -- added grantor_id
u_grantor.rolname::information_schema.sql_identifier AS grantor,
grantee.oid AS grantee_id, -- added grantor_id
grantee.rolname::information_schema.sql_identifier AS grantee,
current_database()::information_schema.sql_identifier AS table_catalog,
nc.nspname::information_schema.sql_identifier AS table_schema,
c.relname::information_schema.sql_identifier AS table_name,
c.prtype::information_schema.character_data AS privilege_type,
CASE
WHEN pg_has_role(grantee.oid, c.relowner, 'USAGE'::text) OR c.grantable THEN 'YES'::text
ELSE 'NO'::text
END::information_schema.yes_or_no AS is_grantable,
CASE
WHEN c.prtype = 'SELECT'::text THEN 'YES'::text
ELSE 'NO'::text
END::information_schema.yes_or_no AS with_hierarchy
FROM (SELECT pg_class.oid,
pg_class.relname,
pg_class.relnamespace,
pg_class.relkind,
pg_class.relowner,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).grantor AS grantor,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).grantee AS grantee,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).privilege_type AS privilege_type,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).is_grantable AS is_grantable
FROM pg_class) c(oid, relname, relnamespace, relkind, relowner, grantor, grantee, prtype, grantable),
pg_namespace nc,
pg_authid u_grantor,
(SELECT pg_authid.oid,
pg_authid.rolname
FROM pg_authid
UNION ALL
SELECT 0::oid AS oid,
'PUBLIC'::name) grantee(oid, rolname)
WHERE c.relnamespace = nc.oid
AND (c.relkind = ANY (ARRAY ['r'::"char", 'v'::"char", 'f'::"char", 'p'::"char"]))
AND c.grantee = grantee.oid
AND c.grantor = u_grantor.oid
AND (c.prtype = ANY (ARRAY ['INSERT'::text, 'SELECT'::text, 'UPDATE'::text, 'DELETE'::text, 'TRUNCATE'::text, 'REFERENCES'::text, 'TRIGGER'::text]))
AND (pg_has_role(u_grantor.oid, 'USAGE'::text) OR pg_has_role(grantee.oid, 'USAGE'::text) OR grantee.rolname = 'PUBLIC'::name)
)
SELECT table_privileges.grantor,
table_privileges.grantor_id, -- added grantor_id
table_privileges.grantee,
table_privileges.grantee_id, -- added grantor_id
table_privileges.table_catalog,
table_privileges.table_schema,
table_privileges.table_name,
table_privileges.privilege_type,
table_privileges.is_grantable,
table_privileges.with_hierarchy
FROM _table_table_privileges table_privileges
WHERE (table_privileges.grantor::name IN (SELECT enabled_roles.role_name
FROM information_schema.enabled_roles))
OR (table_privileges.grantee::name IN (SELECT enabled_roles.role_name
FROM information_schema.enabled_roles));


-- very important thing which property handles "PUBLIC", not PUBLIC role. They are not the same
create temporary view _role_column_grants(grantor, grantor_id, grantee, grantee_id, table_catalog, table_schema, table_name, column_name, privilege_type, is_grantable) as
with
_column_privileges as (
SELECT u_grantor.rolname::information_schema.sql_identifier AS grantor,
u_grantor.oid AS grantor_id, -- added grantor_id
grantee.rolname::information_schema.sql_identifier AS grantee,
grantee.oid AS grantee_id, -- added grantor_id
current_database()::information_schema.sql_identifier AS table_catalog,
nc.nspname::information_schema.sql_identifier AS table_schema,
x.relname::information_schema.sql_identifier AS table_name,
x.attname::information_schema.sql_identifier AS column_name,
x.prtype::information_schema.character_data AS privilege_type,
CASE
WHEN pg_has_role(x.grantee, x.relowner, 'USAGE'::text) OR x.grantable THEN 'YES'::text
ELSE 'NO'::text
END::information_schema.yes_or_no AS is_grantable
FROM (SELECT pr_c.grantor,
pr_c.grantee,
a.attname,
pr_c.relname,
pr_c.relnamespace,
pr_c.prtype,
pr_c.grantable,
pr_c.relowner
FROM (SELECT pg_class.oid,
pg_class.relname,
pg_class.relnamespace,
pg_class.relowner,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).grantor AS grantor,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).grantee AS grantee,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).privilege_type AS privilege_type,
(aclexplode(COALESCE(pg_class.relacl, acldefault('r'::"char", pg_class.relowner)))).is_grantable AS is_grantable
FROM pg_class
WHERE pg_class.relkind = ANY (ARRAY ['r'::"char", 'v'::"char", 'f'::"char", 'p'::"char"])) 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,
pr_a.attname,
c.relname,
c.relnamespace,
pr_a.prtype,
pr_a.grantable,
c.relowner
FROM (SELECT a.attrelid,
a.attname,
(aclexplode(COALESCE(a.attacl, acldefault('c'::"char", cc.relowner)))).grantor AS grantor,
(aclexplode(COALESCE(a.attacl, acldefault('c'::"char", cc.relowner)))).grantee AS grantee,
(aclexplode(COALESCE(a.attacl, acldefault('c'::"char", cc.relowner)))).privilege_type AS privilege_type,
(aclexplode(COALESCE(a.attacl, acldefault('c'::"char", cc.relowner)))).is_grantable AS is_grantable
FROM pg_attribute a
JOIN pg_class cc ON a.attrelid = cc.oid
WHERE a.attnum > 0
AND NOT a.attisdropped) pr_a(attrelid, attname, grantor, grantee, prtype, grantable),
pg_class c
WHERE pr_a.attrelid = c.oid
AND (c.relkind = ANY (ARRAY ['r'::"char", 'v'::"char", 'f'::"char", 'p'::"char"]))) x,
pg_namespace nc,
pg_authid u_grantor,
(SELECT pg_authid.oid,
pg_authid.rolname
FROM pg_authid
UNION ALL
SELECT 0::oid AS oid,
'PUBLIC'::name) grantee(oid, rolname)
WHERE x.relnamespace = nc.oid
AND x.grantee = grantee.oid
AND x.grantor = u_grantor.oid
AND (x.prtype = ANY (ARRAY ['INSERT'::text, 'SELECT'::text, 'UPDATE'::text, 'REFERENCES'::text]))
AND (pg_has_role(u_grantor.oid, 'USAGE'::text) OR pg_has_role(grantee.oid, 'USAGE'::text) OR grantee.rolname = 'PUBLIC'::name)
)
SELECT column_privileges.grantor,
column_privileges.grantor_id,
column_privileges.grantee,
column_privileges.grantee_id,
column_privileges.table_catalog,
column_privileges.table_schema,
column_privileges.table_name,
column_privileges.column_name,
column_privileges.privilege_type,
column_privileges.is_grantable
FROM _column_privileges column_privileges
WHERE (column_privileges.grantor::name IN (SELECT enabled_roles.role_name
FROM information_schema.enabled_roles))
OR (column_privileges.grantee::name IN (SELECT enabled_roles.role_name
FROM information_schema.enabled_roles));






raise debug 'flush previous ddl';
delete from
public.deps_saved_ddl
Expand Down Expand Up @@ -286,7 +446,11 @@ begin
privilege_type,
table_schema,
table_name,
grantee,
case
-- see #13
when grantee_id = 0 then 'public'
else grantee
end,
case
when is_grantable = 'YES' -- or with_hierarchy = 'YES'
then format(
Expand All @@ -300,7 +464,7 @@ begin
end
)
from
information_schema.role_table_grants
_role_table_grants
where
table_schema = v_curr.obj_schema and
table_name = v_curr.obj_name;
Expand Down Expand Up @@ -398,7 +562,11 @@ begin
column_name,
table_schema,
table_name,
grantee,
case
-- see #13
when grantee_id = 0 then 'public'
else grantee
end,
case
when is_grantable = 'YES'
then format(
Expand All @@ -411,7 +579,7 @@ begin
end
)
from
information_schema.role_column_grants
_role_column_grants
where
table_schema = v_curr.obj_schema and
table_name = v_curr.obj_name;
Expand Down
67 changes: 67 additions & 0 deletions tests/feature-13.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
-- @see https://github.com/rvkulikov/pg-deps-management/issues/5
-- I have tried to drop a view so that I can modify it, while retaining all the existing dependencies,
-- however it seems that when I provide a view name to this function, it does not capture any dependencies
-- for the view.

drop schema if exists util cascade;
create schema util;

create or replace function util.__assert(condition boolean, message text) returns void as $$
begin
if not condition then
raise exception 'Asserting failed: %', message;
end if;
end;
$$ language plpgsql;

drop schema if exists feature13 cascade;
create schema feature13;

create role "PUBLIC";

delete from public.deps_saved_ddl where true;

create table feature13.table (col_1 text, col_2 text);
create view feature13.view as select * from feature13.table;

grant select on feature13.view to public;
grant insert on feature13.view to "PUBLIC";
grant select (col_1) on feature13.view to "PUBLIC";
grant update (col_2) on feature13.view to "PUBLIC";
grant update (col_2) on feature13.view to public;

select public.deps_save_and_drop_dependencies(
'feature13',
'table',
'{
"dry_run": false,
"verbose": true,
"populate_materialized_view": true
}'
);

select * from public.deps_saved_ddl;

select
util.__assert(
(select count(true) from public.deps_saved_ddl where trim(' ' from ddl_statement) = 'GRANT SELECT ON feature13.view TO public') = 1,
'Default PUBLIC role table grants ok'::text
);

select
util.__assert(
(select count(true) from public.deps_saved_ddl where trim(' ' from ddl_statement) = 'GRANT INSERT ON feature13.view TO "PUBLIC"') = 1,
'Custom "PUBLIC" role table grants ok'::text
);

select
util.__assert(
(select count(true) from public.deps_saved_ddl where trim(' ' from ddl_statement) = 'GRANT UPDATE (col_2) ON feature13.view TO public') = 1,
'Default PUBLIC role column grants ok'::text
);

select
util.__assert(
(select count(true) from public.deps_saved_ddl where trim(' ' from ddl_statement) = 'GRANT UPDATE (col_2) ON feature13.view TO "PUBLIC"') = 1,
'Custom "PUBLIC" role column grants ok'::text
);

0 comments on commit 1ac47cb

Please sign in to comment.