Skip to content

Commit

Permalink
Add trigger function to enforce row-level security on sequencing tables.
Browse files Browse the repository at this point in the history
Adds trigger functions to ensure that row-level security for sequencing data matches the security in place on the corresponding sample record.

The `access_role` value is initially set on the sample record (enforced with a check constraint) and then must match across related sequencing records (enforced with these trigger functions).
  • Loading branch information
davereinhart committed Aug 17, 2023
1 parent 8a6c145 commit 4e2f31f
Show file tree
Hide file tree
Showing 12 changed files with 360 additions and 4 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- Deploy seattleflu/id3c-customizations:warehouse/consensus-genome/check-consensus-genome-rls to pg

begin;

create or replace function warehouse.check_consensus_genome_rls() returns trigger as $$
begin
if (new.access_role is null and exists(select * from warehouse.sample where sample_id = new.sample_id and access_role is null)) or
(new.access_role is not null and exists(select * from warehouse.sample where sample_id = new.sample_id and access_role::text = new.access_role::text)) then
return new;
else
raise exception 'sample_id %: access_role value for sample and consensus_genome must match', new.sample_id using errcode = 'triggered_action_exception';
end if;
end;

$$
language plpgsql
stable;

create trigger check_consensus_genome_rls before insert or update on warehouse.consensus_genome
for each row execute procedure warehouse.check_consensus_genome_rls();

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
-- Deploy seattleflu/id3c-customizations:warehouse/genomic-sequence/check-genomic-sequence-rls to pg

begin;

create or replace function warehouse.check_genomic_sequence_rls() returns trigger as $$
begin
if (new.access_role is null and
exists(
select *
from warehouse.consensus_genome
where consensus_genome_id = new.consensus_genome_id and access_role is null)) or
(new.access_role is not null and
exists(
select *
from warehouse.consensus_genome
where consensus_genome_id = new.consensus_genome_id and access_role::text = new.access_role::text)) then
return new;
else
raise exception 'consensus_genome_id %: access_role value for consensus genome id and genomic sequence must match', new.consensus_genome_id using errcode = 'triggered_action_exception';
end if;
end;

$$
language plpgsql
stable;

create trigger check_genomic_sequence_rls before insert or update on warehouse.genomic_sequence
for each row execute procedure warehouse.check_genomic_sequence_rls();

commit;
7 changes: 5 additions & 2 deletions schema/deploy/warehouse/sample/cascadia-rls-constraint.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,8 +5,11 @@ begin;

alter table warehouse.sample
add constraint cascadia_rls check(
(lower(details ->> 'sample_origin') != 'cascadia') or
(details ->> 'sample_origin' = 'cascadia' AND access_role::text = 'cascadia'::text)
not (details ? 'sample_origin') or
(
(lower(details ->> 'sample_origin') != 'cascadia' and access_role::text != 'cascadia'::text) or
(lower(details ->> 'sample_origin') = 'cascadia' and access_role::text = 'cascadia'::text)
)
);

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- Deploy seattleflu/id3c-customizations:warehouse/sequence-read-set/check-sequence-read-set-rls to pg

begin;

create or replace function warehouse.check_sequence_read_set_rls() returns trigger as $$
begin
if (new.access_role is null and exists(select * from warehouse.sample where sample_id = new.sample_id and access_role is null)) or
(new.access_role is not null and exists(select * from warehouse.sample where sample_id = new.sample_id and access_role::text = new.access_role::text)) then
return new;
else
raise exception 'sample_id %: access_role value for sample and sequence_read_set must match', new.sample_id using errcode = 'triggered_action_exception';
end if;
end;

$$
language plpgsql
stable;

create trigger check_sequence_read_set_rls before insert or update on warehouse.sequence_read_set
for each row execute procedure warehouse.check_sequence_read_set_rls();

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Revert seattleflu/id3c-customizations:warehouse/consensus-genome/check-consensus-genome-rls from pg

begin;

drop trigger if exists check_consensus_genome_rls on warehouse.consensus_genome;
drop function if exists warehouse.check_consensus_genome_rls;

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Revert seattleflu/id3c-customizations:warehouse/genomic-sequence/check-genomic-sequence-rls from pg

begin;

drop trigger if exists check_genomic_sequence_rls on warehouse.genomic_sequence;
drop function if exists warehouse.check_genomic_sequence_rls;

commit;
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Revert seattleflu/id3c-customizations:warehouse/sequence-read-set/check-sequence-read-set-rls from pg

begin;

drop trigger if exists check_sequence_read_set_rls on warehouse.sequence_read_set;
drop function if exists warehouse.check_sequence_read_set_rls;

commit;
4 changes: 4 additions & 0 deletions schema/sqitch.plan
Original file line number Diff line number Diff line change
Expand Up @@ -494,3 +494,7 @@ shipping/views [shipping/views@2022-12-02] 2023-07-28T16:23:19Z Dave Reinhart <d
roles/cascadia/create 2023-08-16T18:36:25Z Dave Reinhart <davidrr@uw.edu> # Add cascadia role for row-level access.
warehouse/sample/cascadia-rls-constraint 2023-08-16T21:22:54Z Dave Reinhart <davidrr@uw.edu> # Add constraint to ensure row-level security on Cascadia samples.
@2023-08-16 2023-08-16T21:33:13Z Dave Reinhart <davidrr@uw.edu> # Schema as of 16 August 2023

warehouse/consensus-genome/check-consensus-genome-rls 2023-08-16T22:15:21Z Dave Reinhart <davidrr@uw.edu> # Add trigger to ensure row-level security is set on consensus genome records.
warehouse/sequence-read-set/check-sequence-read-set-rls 2023-08-16T23:13:21Z Dave Reinhart <davidrr@uw.edu> # Add trigger to ensure row-level security is set on sequence read set records.
warehouse/genomic-sequence/check-genomic-sequence-rls 2023-08-16T23:18:42Z Dave Reinhart <davidrr@uw.edu> # Add trigger to ensure row-level security is set on genomic sequence records.
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
-- Verify seattleflu/id3c-customizations:warehouse/consensus-genome/check-consensus-genome-rls on pg

begin;

do $$
declare
cascadia_sample_id int;
other_sample_id int;
organism int;
begin
select organism_id into organism from warehouse.organism limit 1;

insert into warehouse.sample (identifier, access_role)
values (uuid_generate_v4(), 'cascadia') returning sample_id into cascadia_sample_id;

insert into warehouse.sample (identifier)
values (uuid_generate_v4()) returning sample_id into other_sample_id;

insert into warehouse.consensus_genome (sample_id, organism_id, access_role)
values (cascadia_sample_id, organism, 'cascadia');

insert into warehouse.consensus_genome (sample_id, organism_id)
values (other_sample_id, organism);

-- these next two inserts should fail silently, with assert statement below to confirm zero count
begin
insert into warehouse.consensus_genome (sample_id, organism_id)
values (cascadia_sample_id, organism);
exception
when triggered_action_exception then null;
end;

begin
insert into warehouse.consensus_genome (sample_id, organism_id, access_role)
values (other_sample_id, organism, 'cascadia');
exception
when triggered_action_exception then null;
end;

-- check expected counts

assert 2 = (
select count(*)
from warehouse.sample
where sample_id in (cascadia_sample_id, other_sample_id)
);

assert 0 = (
select count(*)
from warehouse.consensus_genome
where (access_role is null and sample_id = cascadia_sample_id) or
(access_role::text = 'cascadia' and sample_id = other_sample_id)
);

set local role reporter;

assert 1 = (
select count(*)
from warehouse.consensus_genome
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

set local role cascadia;

assert 2 = (
select count(*)
from warehouse.consensus_genome
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

end
$$;


rollback;
Original file line number Diff line number Diff line change
@@ -0,0 +1,98 @@
-- Verify seattleflu/id3c-customizations:warehouse/genomic-sequence/check-genomic-sequence-rls on pg

begin;

do $$
declare
cascadia_sample_id int;
cascadia_consensus_genome_id int;
other_sample_id int;
other_consensus_genome_id int;
organism int;
begin
select organism_id into organism from warehouse.organism limit 1;

insert into warehouse.sample (identifier, access_role)
values (uuid_generate_v4(), 'cascadia') returning sample_id into cascadia_sample_id;

insert into warehouse.sample (identifier)
values (uuid_generate_v4()) returning sample_id into other_sample_id;

insert into warehouse.consensus_genome (sample_id, organism_id, access_role)
values (cascadia_sample_id, organism, 'cascadia') returning consensus_genome_id into cascadia_consensus_genome_id;

insert into warehouse.consensus_genome (sample_id, organism_id)
values (other_sample_id, organism) returning consensus_genome_id into other_consensus_genome_id;

insert into warehouse.genomic_sequence (consensus_genome_id, identifier, segment, seq, access_role)
values (cascadia_consensus_genome_id, uuid_generate_v4()::text, '', '', 'cascadia');

insert into warehouse.genomic_sequence (consensus_genome_id, identifier, segment, seq)
values (other_consensus_genome_id, uuid_generate_v4()::text, '', '');

-- these next two inserts should fail silently, with assert statement below to confirm zero count
begin
insert into warehouse.genomic_sequence (consensus_genome_id, identifier, segment, seq)
values (cascadia_consensus_genome_id, uuid_generate_v4()::text, '', '');
exception
when triggered_action_exception then null;
end;

begin
insert into warehouse.genomic_sequence (consensus_genome_id, identifier, segment, seq, access_role)
values (other_consensus_genome_id, uuid_generate_v4()::text, '', '', 'cascadia');
exception
when triggered_action_exception then null;
end;

-- check expected counts
assert 2 = (
select count(*)
from warehouse.sample
where sample_id in (cascadia_sample_id, other_sample_id)
);

assert 0 = (
select count(*)
from warehouse.genomic_sequence
where (access_role is null and consensus_genome_id = cascadia_consensus_genome_id) or
(access_role::text = 'cascadia' and consensus_genome_id = other_consensus_genome_id)
);

set local role cascadia;

assert 2 = (
select count(*)
from warehouse.consensus_genome
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

assert 2 = (
select count(*)
from warehouse.genomic_sequence
where (access_role::text = 'cascadia' and consensus_genome_id = cascadia_consensus_genome_id) or
(access_role is null and consensus_genome_id = other_consensus_genome_id)
);

set local role reporter;

assert 1 = (
select count(*)
from warehouse.consensus_genome
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

assert 1 = (
select count(*)
from warehouse.genomic_sequence
where (access_role::text = 'cascadia' and consensus_genome_id = cascadia_consensus_genome_id) or
(access_role is null and consensus_genome_id = other_consensus_genome_id)
);

end
$$;


rollback;
4 changes: 2 additions & 2 deletions schema/verify/warehouse/sample/cascadia-rls-constraint.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,8 @@ do $$
declare
sample_number int;
begin
insert into warehouse.sample (identifier, access_role)
values (uuid_generate_v4(), 'cascadia') returning sample_id into sample_number;
insert into warehouse.sample (identifier, details, access_role)
values (uuid_generate_v4(), '{"sample_origin": "cascadia"}'::jsonb, 'cascadia') returning sample_id into sample_number;

set local role reporter;

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,76 @@
-- Verify seattleflu/id3c-customizations:warehouse/sequence-read-set/check-sequence-read-set-rls on pg

begin;

do $$
declare
cascadia_sample_id int;
other_sample_id int;
organism int;
begin
select organism_id into organism from warehouse.organism limit 1;

insert into warehouse.sample (identifier, access_role)
values (uuid_generate_v4(), 'cascadia') returning sample_id into cascadia_sample_id;

insert into warehouse.sample (identifier)
values (uuid_generate_v4()) returning sample_id into other_sample_id;

insert into warehouse.sequence_read_set (sample_id, access_role, urls)
values (cascadia_sample_id, 'cascadia', array[uuid_generate_v4()::text]);

insert into warehouse.sequence_read_set (sample_id, urls)
values (other_sample_id, array[uuid_generate_v4()::text]);

-- these next two inserts should fail silently, with assert statement below to confirm zero count
begin
insert into warehouse.sequence_read_set (sample_id)
values (cascadia_sample_id);
exception
when triggered_action_exception then null;
end;

begin
insert into warehouse.sequence_read_set (sample_id, access_role, urls)
values (other_sample_id, 'cascadia', array[uuid_generate_v4()::text]);
exception
when triggered_action_exception then null;
end;

-- check expected counts
assert 2 = (
select count(*)
from warehouse.sample
where sample_id in (cascadia_sample_id, other_sample_id)
);

assert 0 = (
select count(*)
from warehouse.sequence_read_set
where (access_role is null and sample_id = cascadia_sample_id) or
(access_role::text = 'cascadia' and sample_id = other_sample_id)
);

set local role cascadia;

assert 2 = (
select count(*)
from warehouse.sequence_read_set
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

set local role reporter;

assert 1 = (
select count(*)
from warehouse.sequence_read_set
where (access_role::text = 'cascadia' and sample_id = cascadia_sample_id) or
(access_role is null and sample_id = other_sample_id)
);

end
$$;


rollback;

0 comments on commit 4e2f31f

Please sign in to comment.