diff --git a/deploy/expense_attachment.sql b/deploy/expense_attachment.sql new file mode 100644 index 0000000..c7dff5f --- /dev/null +++ b/deploy/expense_attachment.sql @@ -0,0 +1,31 @@ +-- Deploy numerus:expense_attachment to pg +-- requires: schema_numerus +-- requires: expense + +begin; + +set search_path to numerus, public; + +create table expense_attachment ( + expense_id integer not null primary key references expense, + original_filename text not null, + mime_type text not null, + content bytea not null +); + +grant select, insert, update, delete on table expense_attachment to invoicer; +grant select, insert, update, delete on table expense_attachment to admin; + +alter table expense_attachment enable row level security; + +create policy company_policy +on expense_attachment +using ( + exists( + select 1 + from expense + where expense.expense_id = expense_attachment.expense_id + ) +); + +commit; diff --git a/revert/expense_attachment.sql b/revert/expense_attachment.sql new file mode 100644 index 0000000..d95b6a4 --- /dev/null +++ b/revert/expense_attachment.sql @@ -0,0 +1,7 @@ +-- Revert numerus:expense_attachment from pg + +begin; + +drop table if exists numerus.expense_attachment; + +commit; diff --git a/sqitch.plan b/sqitch.plan index c00652b..478947e 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -74,3 +74,4 @@ expense [schema_numerus contact company currency_code currency tag_name] 2023-04 expense_tax [schema_numerus expense tax tax_rate] 2023-05-01T14:08:33Z jordi fita mas # Add relation of expense taxes add_expense [schema_numerus expense expense_tax tax company currency parse_price tag_name] 2023-05-02T08:00:26Z jordi fita mas # Add function to create new expenses edit_expense [schema_numerus expense currency parse_price tax tag_name] 2023-05-04T09:53:04Z jordi fita mas # Add function to edit expenses +expense_attachment [schema_numerus expense] 2023-05-13T19:11:21Z jordi fita mas # Add relation of expense attachments diff --git a/test/expense_attachment.sql b/test/expense_attachment.sql new file mode 100644 index 0000000..8fc2fe3 --- /dev/null +++ b/test/expense_attachment.sql @@ -0,0 +1,145 @@ +-- Test expense_attachment +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(29); + +set search_path to numerus, auth, public; + +select has_table('expense_attachment'); +select has_pk('expense_attachment' ); +select table_privs_are('expense_attachment', 'guest', array []::text[]); +select table_privs_are('expense_attachment', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); +select table_privs_are('expense_attachment', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']); +select table_privs_are('expense_attachment', 'authenticator', array []::text[]); + +select has_column('expense_attachment', 'expense_id'); +select col_is_pk('expense_attachment', 'expense_id'); +select col_is_fk('expense_attachment', 'expense_id'); +select fk_ok('expense_attachment', 'expense_id', 'expense', 'expense_id'); +select col_type_is('expense_attachment', 'expense_id', 'integer'); +select col_not_null('expense_attachment', 'expense_id'); +select col_hasnt_default('expense_attachment', 'expense_id'); + +select has_column('expense_attachment', 'original_filename'); +select col_type_is('expense_attachment', 'original_filename', 'text'); +select col_not_null('expense_attachment', 'original_filename'); +select col_hasnt_default('expense_attachment', 'original_filename'); + +select has_column('expense_attachment', 'mime_type'); +select col_type_is('expense_attachment', 'mime_type', 'text'); +select col_not_null('expense_attachment', 'mime_type'); +select col_hasnt_default('expense_attachment', 'mime_type'); + +select has_column('expense_attachment', 'content'); +select col_type_is('expense_attachment', 'content', 'bytea'); +select col_not_null('expense_attachment', 'content'); +select col_hasnt_default('expense_attachment', 'content'); + + +set client_min_messages to warning; +truncate expense_attachment cascade; +truncate expense cascade; +truncate invoice cascade; +truncate tax cascade; +truncate tax_class cascade; +truncate contact cascade; +truncate company_user cascade; +truncate payment_method cascade; +truncate company cascade; +truncate auth."user" cascade; +reset client_min_messages; + +insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at) +values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month') + , (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month') +; + +set constraints "company_default_payment_method_id_fkey" deferred; + +insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id) +values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222) + , (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (444, 4, 'cash', 'cash') + , (222, 2, 'cash', 'cash') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into company_user (company_id, user_id) +values (2, 1) + , (4, 5) +; + +insert into tax_class (tax_class_id, company_id, name) +values (22, 2, 'vat') + , (44, 4, 'vat') +; + +insert into tax (tax_id, company_id, tax_class_id, name, rate) +values (3, 2, 22, 'IVA 21 %', 0.21) + , (6, 4, 44, 'IVA 10 %', 0.10) +; + +insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code) +values ( 9, 2, 'Customer 1', 'XX555', '', '777-777-777', 'c1@e', '', '', '', '', '', 'ES') + , (10, 4, 'Customer 2', 'XX666', '', '888-888-888', 'c2@e', '', '', '', '', '', 'ES') +; + +insert into expense (expense_id, company_id, invoice_number, contact_id, invoice_date, amount, currency_code) +values (13, 2, 'INV001', 9, '2011-01-11', 111, 'EUR') + , (14, 4, 'INV002', 10, '2022-02-22', 222, 'EUR') +; + +insert into expense_attachment (expense_id, original_filename, mime_type, content) +values (13, 'expense.txt', 'text/plain', convert_to('IOU 42', 'UTF8')) + , (14, 'expense.html', 'text/html', convert_to('IOU 42', 'UTF8')) +; + +prepare expense_attachment_data as +select expense_id, original_filename +from expense_attachment +order by expense_id, original_filename; + +set role invoicer; +select is_empty('expense_attachment_data', 'Should show no data when cookie is not set yet'); +reset role; + +select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog'); +select bag_eq( + 'expense_attachment_data', + $$ values (13, 'expense.txt') + $$, + 'Should only list tax of products of the companies where demo@tandem.blog is user of' +); +reset role; + +select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog'); +select bag_eq( + 'expense_attachment_data', + $$ values (14, 'expense.html') + $$, + 'Should only list tax of products of the companies where admin@tandem.blog is user of' +); +reset role; + +select set_cookie('not-a-cookie'); +select throws_ok( + 'expense_attachment_data', + '42501', 'permission denied for table expense_attachment', + 'Should not allow select to guest users' +); +reset role; + + +select * +from finish(); + +rollback; + diff --git a/verify/expense_attachment.sql b/verify/expense_attachment.sql new file mode 100644 index 0000000..48ccde2 --- /dev/null +++ b/verify/expense_attachment.sql @@ -0,0 +1,15 @@ +-- Verify numerus:expense_attachment on pg + +begin; + +select expense_id + , original_filename + , mime_type + , content +from numerus.expense_attachment +where false; + +select 1 / count(*) from pg_class where oid = 'numerus.expense_attachment'::regclass and relrowsecurity; +select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.expense_attachment'::regclass; + +rollback;