Add media relation and add_media function

This commit is contained in:
jordi fita mas 2023-09-08 20:03:26 +02:00
parent ac46759df4
commit de0fac1368
13 changed files with 484 additions and 0 deletions

27
deploy/add_media.sql Normal file
View File

@ -0,0 +1,27 @@
-- Deploy camper:add_media to pg
-- requires: roles
-- requires: schema_camper
-- requires: media
-- requires: media_type
begin;
set search_path to camper, public;
create or replace function add_media(company integer, filename text, media_type media_type, content bytea) returns integer as
$$
insert into media (company_id, original_filename, media_type, content)
values (company, filename, media_type, content)
on conflict (company_id, hash) do update
set original_filename = excluded.original_filename
, media_type = excluded.media_type
returning media_id
;
$$
language sql
;
revoke execute on function add_media(integer, text, media_type, bytea) from public;
grant execute on function add_media(integer, text, media_type, bytea) to admin;
commit;

60
deploy/media.sql Normal file
View File

@ -0,0 +1,60 @@
-- Deploy camper:media to pg
-- requires: roles
-- requires: schema_camper
-- requires: company
-- requires: user_profile
-- requires: media_type
begin;
set search_path to camper, public;
create table media (
media_id serial not null primary key,
company_id integer not null references company,
hash bytea not null generated always as (sha256(content)) stored,
original_filename text not null constraint original_filename_not_empty check(length(trim(original_filename)) > 0),
media_type media_type not null,
content bytea not null,
unique (company_id, hash)
);
grant select on table media to guest;
grant select on table media to employee;
grant select, insert, delete, update on table media to admin;
grant usage on sequence media_media_id_seq to admin;
alter table media enable row level security;
create policy guest_ok
on media
for select
using (true)
;
create policy insert_to_company
on media
for insert
with check (
company_id in (select company_id from user_profile)
)
;
create policy update_company
on media
for update
using (
company_id in (select company_id from user_profile)
)
;
create policy delete_from_company
on media
for delete
using (
company_id in (select company_id from user_profile)
)
;
commit;

16
deploy/media_type.sql Normal file
View File

@ -0,0 +1,16 @@
-- Deploy camper:media_type to pg
-- requires: schema_camper
begin;
set search_path to camper, public;
-- regular expression combining https://www.rfc-editor.org/rfc/rfc2045#section-5.1 and https://www.rfc-editor.org/rfc/rfc7231#section-3.1.1.1
-- should be case insensitive, but in this application we only use lower case.
create domain media_type as text
check (value ~ '(application|audio|font|example|image|message|model|multipart|text|video|x-(?:[0-9A-Za-z!#$%&''*+.^_`|~-]+))/([0-9A-Za-z!#$%&''*+.^_`|~-]+)((?:[ \t]*;[ \t]*[0-9A-Za-z!#$%&''*+.^_`|~-]+=(?:[0-9A-Za-z!#$%&''*+.^_`|~-]+|"(?:[^"\\]|\.)*"))*)')
;
comment on domain media_type is 'Also known as MIME type. Always lower case.';
commit;

7
revert/add_media.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert camper:add_media from pg
begin;
drop function if exists camper.add_media(integer, text, camper.media_type, bytea);
commit;

7
revert/media.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert camper:media from pg
begin;
drop table if exists camper.media;
commit;

7
revert/media_type.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert camper:media_type from pg
begin;
drop domain if exists camper.media_type;
commit;

View File

@ -53,3 +53,6 @@ to_color [roles schema_camper color] 2023-08-16T13:11:32Z jordi fita mas <jordi@
season [roles schema_camper company user_profile] 2023-08-16T13:21:28Z jordi fita mas <jordi@tandem.blog> # Add relation of (tourist) season
add_season [roles schema_camper season color to_integer] 2023-08-16T16:59:17Z jordi fita mas <jordi@tandem.blog> # Add function to create seasons
edit_season [roles schema_camper season color to_integer] 2023-08-16T17:09:02Z jordi fita mas <jordi@tandem.blog> # Add function to update seasons
media_type [schema_camper] 2023-09-08T17:17:02Z jordi fita mas <jordi@tandem.blog> # Add domain for media type
media [roles schema_camper company user_profile media_type] 2023-09-08T16:50:55Z jordi fita mas <jordi@tandem.blog> # Add relation of uploaded media
add_media [roles schema_camper media media_type] 2023-09-08T17:40:28Z jordi fita mas <jordi@tandem.blog> # Add function to create media

60
test/add_media.sql Normal file
View File

@ -0,0 +1,60 @@
-- Test add_media
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
set search_path to camper, public;
select plan(13);
select has_function('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea']);
select function_lang_is('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'sql');
select function_returns('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'integer');
select isnt_definer('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea']);
select volatility_is('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'volatile');
select function_privs_are('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'guest', array[]::text[]);
select function_privs_are('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'employee', array[]::text[]);
select function_privs_are('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'admin', array['EXECUTE']);
select function_privs_are('camper', 'add_media', array ['integer', 'text', 'media_type', 'bytea'], 'authenticator', array[]::text[]);
set client_min_messages to warning;
truncate media cascade;
truncate company cascade;
reset client_min_messages;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_lang_tag)
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 'ca')
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 'ca')
;
select lives_ok(
$$ select add_media(1, 'text.txt', 'text/plain', 'hello, world!') $$,
'Should be able to add a media to the first company'
);
select lives_ok(
$$ select add_media(2, 'image.svg', 'image/svg+xml', '<svg xmlns="http://www.w3.org/2000/svg" width="1" height="1"/>') $$,
'Should be able to add a media to the second company'
);
select lives_ok(
$$ select add_media(2, 'world.txt', 'text/plain', 'hello, world!') $$,
'Should be able to add a media to the second company with the same content as the file from the first company'
);
select bag_eq(
$$ select company_id, hash, original_filename, media_type, convert_from(content, 'utf-8') from media $$,
$$ values (1, sha256('hello, world!'), 'text.txt', 'text/plain', 'hello, world!')
, (2, sha256('<svg xmlns="http://www.w3.org/2000/svg" width="1" height="1"/>'), 'image.svg', 'image/svg+xml', '<svg xmlns="http://www.w3.org/2000/svg" width="1" height="1"/>')
, (2, sha256('hello, world!'), 'world.txt', 'text/plain', 'hello, world!')
$$,
'Should have added all three media'
);
select *
from finish();
rollback;

207
test/media.sql Normal file
View File

@ -0,0 +1,207 @@
-- Test media
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(55);
set search_path to camper, public;
select has_table('media');
select has_pk('media');
select col_is_unique('media', array['company_id', 'hash']);
select table_privs_are('media', 'guest', array['SELECT']);
select table_privs_are('media', 'employee', array['SELECT']);
select table_privs_are('media', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('media', 'authenticator', array[]::text[]);
select has_sequence('media_media_id_seq');
select sequence_privs_are('media_media_id_seq', 'guest', array[]::text[]);
select sequence_privs_are('media_media_id_seq', 'employee', array[]::text[]);
select sequence_privs_are('media_media_id_seq', 'admin', array['USAGE']);
select sequence_privs_are('media_media_id_seq', 'authenticator', array[]::text[]);
select has_column('media', 'media_id');
select col_is_pk('media', 'media_id');
select col_type_is('media', 'media_id', 'integer');
select col_not_null('media', 'media_id');
select col_has_default('media', 'media_id');
select col_default_is('media', 'media_id', 'nextval(''media_media_id_seq''::regclass)');
select has_column('media', 'company_id');
select col_is_fk('media', 'company_id');
select fk_ok('media', 'company_id', 'company', 'company_id');
select col_type_is('media', 'company_id', 'integer');
select col_not_null('media', 'company_id');
select col_hasnt_default('media', 'company_id');
select has_column('media', 'hash');
select col_type_is('media', 'hash', 'bytea');
select col_not_null('media', 'hash');
select col_has_default('media', 'hash');
select col_default_is('media', 'hash', 'sha256(content)');
select has_column('media', 'original_filename');
select col_type_is('media', 'original_filename', 'text');
select col_not_null('media', 'original_filename');
select col_hasnt_default('media', 'original_filename');
select has_column('media', 'media_type');
select col_type_is('media', 'media_type', 'media_type');
select col_not_null('media', 'media_type');
select col_hasnt_default('media', 'media_type');
select has_column('media', 'content');
select col_type_is('media', 'content', 'bytea');
select col_not_null('media', 'content');
select col_hasnt_default('media', 'content');
set client_min_messages to warning;
truncate media cascade;
truncate company_host cascade;
truncate company_user cascade;
truncate company cascade;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_lang_tag)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 'ca')
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 'ca')
;
insert into company_user (company_id, user_id, role)
values (2, 1, 'admin')
, (4, 5, 'admin')
;
insert into company_host (company_id, host)
values (2, 'co2')
, (4, 'co4')
;
insert into media (company_id, original_filename, media_type, content)
values (2, 'text2.txt', 'text/plain', 'content2')
, (4, 'text4.txt', 'text/plain', 'content4')
;
prepare media_data as
select company_id, original_filename
from media
order by company_id, original_filename;
set role guest;
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (4, 'text4.txt')
$$,
'Everyone should be able to list all media across all companies'
);
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog', 'co2');
select lives_ok(
$$ insert into media(company_id, original_filename, media_type, content)
values (2, 'text2-2.txt', 'text/plain', sha256('Another media')) $$,
'Admin from company 2 should be able to insert a new media to that company.'
);
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (2, 'text2-2.txt')
, (4, 'text4.txt')
$$,
'The new row should have been added'
);
select lives_ok(
$$ update media set original_filename = 'text2_2.txt' where company_id = 2 and original_filename = 'text2-2.txt' $$,
'Admin from company 2 should be able to update media of that company.'
);
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (2, 'text2_2.txt')
, (4, 'text4.txt')
$$,
'The row should have been updated.'
);
select lives_ok(
$$ delete from media where company_id = 2 and original_filename = 'text2_2.txt' $$,
'Admin from company 2 should be able to delete media from that company.'
);
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (4, 'text4.txt')
$$,
'The row should have been deleted.'
);
select throws_ok(
$$ insert into media (company_id, original_filename, media_type, content)
values (4, 'text4-2.txt', 'text/plain', 'Another media') $$,
'42501', 'new row violates row-level security policy for table "media"',
'Admin from company 2 should NOT be able to insert new media to company 4.'
);
select lives_ok(
$$ update media set original_filename = 'nope.txt' where company_id = 4 $$,
'Admin from company 2 should not be able to update new media of company 4, but no error if company_id is not changed.'
);
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (4, 'text4.txt')
$$,
'No row should have been changed.'
);
select throws_ok(
$$ update media set company_id = 4 where company_id = 2 $$,
'42501', 'new row violates row-level security policy for table "media"',
'Admin from company 2 should NOT be able to move media to company 4'
);
select lives_ok(
$$ delete from media where company_id = 4 $$,
'Admin from company 2 should NOT be able to delete media from company 4, but not error is thrown'
);
select bag_eq(
'media_data',
$$ values (2, 'text2.txt')
, (4, 'text4.txt')
$$,
'No row should have been changed'
);
select throws_ok(
$$ insert into media (company_id, original_filename, media_type, content) values (2, ' ', 'text/plain', 'content') $$,
'23514', 'new row for relation "media" violates check constraint "original_filename_not_empty"',
'Should not be able to insert media with a blank filename.'
);
reset role;
select *
from finish();
rollback;

56
test/media_type.sql Normal file
View File

@ -0,0 +1,56 @@
-- Test media_type
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(14);
set search_path to camper, public;
select has_domain('media_type');
select domain_type_is('media_type', 'text');
select lives_ok($$ select 'text/plain'::media_type $$, 'Should accept valid media types');
select lives_ok($$ select 'application/octet-stream'::media_type $$, 'Should accept media types with dashes');
select lives_ok($$ select 'application/x-abiword'::media_type $$, 'Should accept non-standard media types');
select lives_ok($$ select 'application/vnd.openxmlformats-officedocument.wordprocessingml.document'::media_type $$, 'Should accept idiotic, but valid media types');
select lives_ok($$ select 'application/vnd.mozilla.xul+xml'::media_type $$, 'Should accept XML subtypes');
select lives_ok($$ select 'text/html;charset=utf-8'::media_type $$, 'Should accept media types with unquoted parameters');
select lives_ok($$ select 'text/html; charset="utf-8"'::media_type $$, 'Should accept media types with quoted parameters');
select throws_ok(
$$ SELECT ''::media_type $$,
23514, null,
'Should reject empty strings'
);
select throws_ok(
$$ SELECT 'text plain'::media_type $$,
23514, null,
'Should reject types without separator'
);
select throws_ok(
$$ SELECT 'text/'::media_type $$,
23514, null,
'Should reject types without subtype'
);
select throws_ok(
$$ SELECT '/plain'::media_type $$,
23514, null,
'Should reject types without subtype'
);
select throws_ok(
$$ SELECT 'invalid/type'::media_type $$,
23514, null,
'Should reject imaginary types'
);
select *
from finish();
rollback;

7
verify/add_media.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify camper:add_media on pg
begin;
select has_function_privilege('camper.add_media(integer, text, camper.media_type, bytea)', 'execute');
rollback;

20
verify/media.sql Normal file
View File

@ -0,0 +1,20 @@
-- Verify camper:media on pg
begin;
select media_id
, company_id
, hash
, original_filename
, media_type
, content
from camper.media
where false;
select 1 / count(*) from pg_class where oid = 'camper.media'::regclass and relrowsecurity;
select 1 / count(*) from pg_policy where polname = 'guest_ok' and polrelid = 'camper.media'::regclass;
select 1 / count(*) from pg_policy where polname = 'insert_to_company' and polrelid = 'camper.media'::regclass;
select 1 / count(*) from pg_policy where polname = 'update_company' and polrelid = 'camper.media'::regclass;
select 1 / count(*) from pg_policy where polname = 'delete_from_company' and polrelid = 'camper.media'::regclass;
rollback;

7
verify/media_type.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify camper:media_type on pg
begin;
select pg_catalog.has_type_privilege('camper.media_type', 'usage');
rollback;