Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Adding row level security to sample and genomics tables #328

Merged
merged 4 commits into from
Aug 22, 2023
Merged
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 2 additions & 2 deletions schema/deploy/shipping/views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ begin;
-- there needs to be a lag between view development and consumers being
-- updated, copy the view definition into v2 and make changes there.

create or replace view shipping.presence_absence_result_v1 as
create or replace view shipping.presence_absence_result_v1 with (security_invoker = true) as

select sample.identifier as sample,
target.identifier as target,
Expand All @@ -39,7 +39,7 @@ grant select
to "incidence-modeler";


create or replace view shipping.presence_absence_result_v2 as
create or replace view shipping.presence_absence_result_v2 with (security_invoker = true) as

select sample.identifier as sample,
target.identifier as target,
Expand Down
67 changes: 67 additions & 0 deletions schema/deploy/shipping/[email protected]
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
-- Deploy seattleflu/schema:shipping/views to pg
-- requires: shipping/schema
-- requires: functions/array_distinct

-- Hello! All shipping views are defined here. Rework this change with Sqitch
-- to change a view definition or add new views. This workflow helps keep
-- inter-view dependencies manageable.

begin;

-- This view is versioned as a hedge against future changes. Changing this
-- view in place is fine as long as changes are backwards compatible. Think of
-- the version number as the major part of a semantic versioning scheme. If
-- there needs to be a lag between view development and consumers being
-- updated, copy the view definition into v2 and make changes there.

create or replace view shipping.presence_absence_result_v1 as

select sample.identifier as sample,
target.identifier as target,
present,
organism.lineage as organism

from warehouse.sample
join warehouse.presence_absence using (sample_id)
join warehouse.target using (target_id)
left join warehouse.organism using (organism_id)
where target.control = false;

comment on view shipping.presence_absence_result_v1 is
'View of warehoused presence-absence results for modeling and viz teams';

revoke all
on shipping.presence_absence_result_v1
from "incidence-modeler";

grant select
on shipping.presence_absence_result_v1
to "incidence-modeler";


create or replace view shipping.presence_absence_result_v2 as

select sample.identifier as sample,
target.identifier as target,
present,
organism.lineage as organism,
presence_absence.details as details

from warehouse.sample
join warehouse.presence_absence using (sample_id)
join warehouse.target using (target_id)
left join warehouse.organism using (organism_id)
where target.control = false;

comment on view shipping.presence_absence_result_v2 is
'View of warehoused presence-absence results for modeling and viz teams';

revoke all
on shipping.presence_absence_result_v2
from "incidence-modeler";

grant select
on shipping.presence_absence_result_v2
to "incidence-modeler";

commit;
17 changes: 17 additions & 0 deletions schema/deploy/warehouse/consensus-genome/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- Deploy seattleflu/schema:warehouse/consensus-genome/access-role-rls to pg

begin;

alter table warehouse.consensus_genome
add access_role regrole;

create policy consensus_genome_rls
on warehouse.consensus_genome
for all
to public
using (access_role is null or pg_has_role(current_user, access_role, 'usage'));

alter table warehouse.consensus_genome
enable row level security;

commit;
17 changes: 17 additions & 0 deletions schema/deploy/warehouse/genomic-sequence/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- Deploy seattleflu/schema:warehouse/genomic-sequence/access-role-rls to pg

begin;

alter table warehouse.genomic_sequence
add access_role regrole;

create policy genomic_sequence_rls
on warehouse.genomic_sequence
for all
to public
using (access_role is null or pg_has_role(current_user, access_role, 'usage'));

alter table warehouse.genomic_sequence
enable row level security;

commit;
17 changes: 17 additions & 0 deletions schema/deploy/warehouse/sample/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- deploy seattleflu/schema:warehouse/sample/access-role-rls to pg

begin;

alter table warehouse.sample
add access_role regrole;

create policy sample_rls
on warehouse.sample
for all
to public
using (access_role is null or pg_has_role(current_user, access_role, 'usage'));

alter table warehouse.sample
enable row level security;

commit;
17 changes: 17 additions & 0 deletions schema/deploy/warehouse/sequence-read-set/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
-- Deploy seattleflu/schema:warehouse/sequence-read-set/access-role-rls to pg

begin;

alter table warehouse.sequence_read_set
add access_role regrole;

create policy sequence_read_set_rls
on warehouse.sequence_read_set
for all
to public
using (access_role is null or pg_has_role(current_user, access_role, 'usage'));

alter table warehouse.sequence_read_set
enable row level security;

commit;
22 changes: 21 additions & 1 deletion schema/revert/shipping/views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -38,10 +38,30 @@ grant select
on shipping.presence_absence_result_v1
to "incidence-modeler";


create or replace view shipping.presence_absence_result_v2 as

select sample.identifier as sample,
target.identifier as target,
present,
organism.lineage as organism,
presence_absence.details as details

from warehouse.sample
join warehouse.presence_absence using (sample_id)
join warehouse.target using (target_id)
left join warehouse.organism using (organism_id)
where target.control = false;

comment on view shipping.presence_absence_result_v2 is
'View of warehoused presence-absence results for modeling and viz teams';

revoke all
on shipping.presence_absence_result_v2
from "incidence-modeler";

drop view shipping.presence_absence_result_v2;
grant select
on shipping.presence_absence_result_v2
to "incidence-modeler";

commit;
47 changes: 47 additions & 0 deletions schema/revert/shipping/[email protected]
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
-- Deploy seattleflu/schema:shipping/views to pg
-- requires: shipping/schema
-- requires: functions/array_distinct

-- Hello! All shipping views are defined here. Rework this change with Sqitch
-- to change a view definition or add new views. This workflow helps keep
-- inter-view dependencies manageable.

begin;

-- This view is versioned as a hedge against future changes. Changing this
-- view in place is fine as long as changes are backwards compatible. Think of
-- the version number as the major part of a semantic versioning scheme. If
-- there needs to be a lag between view development and consumers being
-- updated, copy the view definition into v2 and make changes there.

create or replace view shipping.presence_absence_result_v1 as

select sample.identifier as sample,
target.identifier as target,
present,
organism.lineage as organism

from warehouse.sample
join warehouse.presence_absence using (sample_id)
join warehouse.target using (target_id)
left join warehouse.organism using (organism_id)
where target.control = false;

comment on view shipping.presence_absence_result_v1 is
'View of warehoused presence-absence results for modeling and viz teams';

revoke all
on shipping.presence_absence_result_v1
from "incidence-modeler";

grant select
on shipping.presence_absence_result_v1
to "incidence-modeler";

revoke all
on shipping.presence_absence_result_v2
from "incidence-modeler";

drop view shipping.presence_absence_result_v2;

commit;
14 changes: 14 additions & 0 deletions schema/revert/warehouse/consensus-genome/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
-- Revert seattleflu/schema:warehouse/consensus-genome/access-role-rls from pg

begin;

alter table warehouse.consensus_genome
disable row level security;

drop policy consensus_genome_rls
on warehouse.consensus_genome;

alter table warehouse.consensus_genome
drop column access_role;

commit;
14 changes: 14 additions & 0 deletions schema/revert/warehouse/genomic-sequence/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
-- Revert seattleflu/schema:warehouse/genomic-sequence/access-role-rls from pg

begin;

alter table warehouse.genomic_sequence
disable row level security;

drop policy genomic_sequence_rls
on warehouse.genomic_sequence;

alter table warehouse.genomic_sequence
drop column access_role;

commit;
14 changes: 14 additions & 0 deletions schema/revert/warehouse/sample/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
-- Revert seattleflu/schema:warehouse/sample/access-role-rls from pg

begin;

alter table warehouse.sample
disable row level security;

drop policy sample_rls
on warehouse.sample;

alter table warehouse.sample
drop column access_role;

commit;
14 changes: 14 additions & 0 deletions schema/revert/warehouse/sequence-read-set/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
-- Revert seattleflu/schema:warehouse/sequence-read-set/access-role-rls from pg

begin;

alter table warehouse.sequence_read_set
disable row level security;

drop policy sequence_read_set_rls
on warehouse.sequence_read_set;

alter table warehouse.sequence_read_set
drop column access_role;

commit;
8 changes: 8 additions & 0 deletions schema/sqitch.plan
Original file line number Diff line number Diff line change
Expand Up @@ -243,3 +243,11 @@ functions/mint_identifiers 2022-07-15T22:13:52Z Dave Reinhart <[email protected]> #

roles/identifier-minter/grants [roles/identifier-minter/grants@2022-07-25] 2022-07-28T19:05:20Z Dave Reinhart <[email protected]> # Add execute permissions on mint_identifiers function to identiifer-minter
@2022-07-28 2022-07-28T19:20:25Z Dave Reinhart <[email protected]> # Schema as of 28 July 2022

warehouse/sample/access-role-rls 2023-07-27T19:39:54Z Dave Reinhart <[email protected]> # Add column to store role name; Implement row-level security on sample table
warehouse/genomic-sequence/access-role-rls 2023-07-27T21:01:44Z Dave Reinhart <[email protected]> # Add column to store role name; Implement row-level security on genomic_sequence table
warehouse/consensus-genome/access-role-rls 2023-07-27T21:13:41Z Dave Reinhart <[email protected]> # Add column to store role name; Implement row-level security on consensus_genome table
warehouse/sequence-read-set/access-role-rls 2023-07-27T21:32:39Z Dave Reinhart <[email protected]> # Add column to store role name; Implement row-level security on sequence_read_set table
@2023-07-27 2023-07-27T21:44:39Z Dave Reinhart <[email protected]> # Schema as of 27 July 2023
shipping/views [shipping/views@2023-07-27] 2023-07-27T22:31:51Z Dave Reinhart <[email protected]> # Add security invoker to shipping views for row-level security
@2023-07-28 2023-07-27T22:41:52Z Dave Reinhart <[email protected]> # Schema as of 28 July 2023
15 changes: 15 additions & 0 deletions schema/verify/shipping/[email protected]
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
-- Verify seattleflu/schema:shipping/views on pg

begin;

select 1/(count(*) = 1)::int
from information_schema.views
where array[table_schema, table_name]::text[]
= pg_catalog.parse_ident('shipping.presence_absence_result_v1');

select 1/(count(*) = 1)::int
from information_schema.views
where array[table_schema, table_name]::text[]
= pg_catalog.parse_ident('shipping.presence_absence_result_v2');

rollback;
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
-- Verify seattleflu/schema:warehouse/consensus-genome/access-role-rls on pg

begin;

rollback;
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
-- Verify seattleflu/schema:warehouse/genomic-sequence/access-role-rls on pg

begin;

rollback;
8 changes: 8 additions & 0 deletions schema/verify/warehouse/sample/access-role-rls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Verify seattleflu/schema:warehouse/sample/access-role-rls on pg

begin;

insert into warehouse.sample (identifier, access_role)
values ('__SAMPLE__', 'postgres');

rollback;
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Verify seattleflu/schema:warehouse/sequence-read-set/access-role-rls on pg

begin;



rollback;