-
Notifications
You must be signed in to change notification settings - Fork 16
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #15 from rvkulikov/feature-13
fix(Grants): fixed PUBLIC and "PUBLIC" role grants
- Loading branch information
Showing
3 changed files
with
267 additions
and
9 deletions.
There are no files selected for viewing
Some generated files are not rendered by default. Learn more about how customized files appear on GitHub.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 | ||
); |