camper/test/media.sql

198 lines
5.9 KiB
MySQL
Raw Normal View History

-- Test media
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
Replace serial columns with ‘generated by default as identity’ I just found out that this is a feature introduced in PostgreSQL 10, back in 2017. Besides this being the standard way to define an “auto incremental column” introduced in SQL:2003[0], called “identity columns”, in PostgreSQL the new syntax has the following pros, according to [1]: * No need to explicitly grant usage on the generated sequence. * Can restart the sequence with only the name of the table and column; no need to know the sequence’s name. * An identity column has no default, and the sequence is better “linked” to the table, therefore you can not drop the default value but leave the sequence around, and, conversely, can not drop the sequence if the column is still defined. Due to this, PostgreSQL’s authors recommendation is to use identity columns instead of serial, unless there is the need for compatibility with PostgreSQL older than 10[2], which is not our case. According to PostgreSQL’s documentation[3], the identity column can be ‘GENERATED BY DEFAULT’ or ‘GENERATED ALWAYS’. In the latter case, it is not possible to give a user-specified value when inserting unless specifying ‘OVERRIDING SYSTEM VALUE’. I think this would make harder to write pgTAP tests, and the old behaviour of serial, which is equivalent to ‘GENERATED BY DEFAULT’, did not bring me any trouble so far. [0]: https://sigmodrecord.org/publications/sigmodRecord/0403/E.JimAndrew-standard.pdf [1]: https://www.2ndquadrant.com/en/blog/postgresql-10-identity-columns/ [2]: https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial [3]: https://www.postgresql.org/docs/15/sql-createtable.html
2023-09-26 17:35:16 +00:00
select plan(41);
set search_path to camper, public;
select has_table('media');
select has_pk('media');
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_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');
Replace serial columns with ‘generated by default as identity’ I just found out that this is a feature introduced in PostgreSQL 10, back in 2017. Besides this being the standard way to define an “auto incremental column” introduced in SQL:2003[0], called “identity columns”, in PostgreSQL the new syntax has the following pros, according to [1]: * No need to explicitly grant usage on the generated sequence. * Can restart the sequence with only the name of the table and column; no need to know the sequence’s name. * An identity column has no default, and the sequence is better “linked” to the table, therefore you can not drop the default value but leave the sequence around, and, conversely, can not drop the sequence if the column is still defined. Due to this, PostgreSQL’s authors recommendation is to use identity columns instead of serial, unless there is the need for compatibility with PostgreSQL older than 10[2], which is not our case. According to PostgreSQL’s documentation[3], the identity column can be ‘GENERATED BY DEFAULT’ or ‘GENERATED ALWAYS’. In the latter case, it is not possible to give a user-specified value when inserting unless specifying ‘OVERRIDING SYSTEM VALUE’. I think this would make harder to write pgTAP tests, and the old behaviour of serial, which is equivalent to ‘GENERATED BY DEFAULT’, did not bring me any trouble so far. [0]: https://sigmodrecord.org/publications/sigmodRecord/0403/E.JimAndrew-standard.pdf [1]: https://www.2ndquadrant.com/en/blog/postgresql-10-identity-columns/ [2]: https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial [3]: https://www.postgresql.org/docs/15/sql-createtable.html
2023-09-26 17:35:16 +00:00
select col_hasnt_default('media', 'media_id');
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', 'content_hash');
select col_is_fk('media', 'content_hash');
select fk_ok('media', 'content_hash', 'media_content', 'content_hash');
select col_type_is('media', 'content_hash', 'bytea');
select col_not_null('media', 'content_hash');
select col_hasnt_default('media', 'content_hash');
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');
set client_min_messages to warning;
truncate media cascade;
truncate media_content 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, rtc_number, tourist_tax, tourist_tax_max_days, country_code, currency_code, default_lang_tag)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', '', 60, 7, 'ES', 'EUR', 'ca')
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', '', 60, 7, '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_content (media_type, bytes)
values ('text/plain', 'content2')
, ('text/plain', 'content4')
, ('text/plain', 'content6')
;
insert into media (company_id, original_filename, content_hash)
values (2, 'text2.txt', sha256('content2'))
, (4, 'text4.txt', sha256('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, content_hash)
values (2, 'text2-6.txt', sha256('content6')) $$,
'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-6.txt')
, (4, 'text4.txt')
$$,
'The new row should have been added'
);
select lives_ok(
$$ update media set original_filename = 'text2_6.txt' where company_id = 2 and original_filename = 'text2-6.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_6.txt')
, (4, 'text4.txt')
$$,
'The row should have been updated.'
);
select lives_ok(
$$ delete from media where company_id = 2 and original_filename = 'text2_6.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, content_hash)
values (4, 'text4-2.txt', sha256('content6')) $$,
'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, content_hash) values (2, ' ', sha256('content6')) $$,
'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;