Add the expense relation
This commit is contained in:
parent
19bcfc29e8
commit
781c935703
|
@ -0,0 +1,47 @@
|
|||
-- Deploy numerus:expense to pg
|
||||
-- requires: schema_numerus
|
||||
-- requires: contact
|
||||
-- requires: company
|
||||
-- requires: currency_code
|
||||
-- requires: currency
|
||||
-- requires: tag_name
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create table expense (
|
||||
expense_id serial primary key,
|
||||
company_id integer not null references company,
|
||||
slug uuid not null unique default gen_random_uuid(),
|
||||
contact_id integer not null references contact,
|
||||
invoice_number text not null,
|
||||
invoice_date date not null,
|
||||
amount integer not null,
|
||||
currency_code currency_code not null references currency,
|
||||
tags tag_name[] not null default '{}',
|
||||
created_at timestamptz not null default current_timestamp
|
||||
);
|
||||
|
||||
create index on expense using gin (tags);
|
||||
|
||||
grant select, insert, update, delete on table expense to invoicer;
|
||||
grant select, insert, update, delete on table expense to admin;
|
||||
|
||||
grant usage on sequence expense_expense_id_seq to invoicer;
|
||||
grant usage on sequence expense_expense_id_seq to admin;
|
||||
|
||||
alter table expense enable row level security;
|
||||
|
||||
create policy company_policy
|
||||
on expense
|
||||
using (
|
||||
exists(
|
||||
select 1
|
||||
from company_user
|
||||
join user_profile using (user_id)
|
||||
where company_user.company_id = expense.company_id
|
||||
)
|
||||
);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:expense from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop table if exists numerus.expense;
|
||||
|
||||
commit;
|
|
@ -70,3 +70,4 @@ edited_invoice_product [schema_numerus discount_rate] 2023-03-11T19:22:24Z jordi
|
|||
edit_invoice [schema_numerus invoice currency parse_price edited_invoice_product tax invoice_product invoice_product_tax tag_name] 2023-03-11T18:30:50Z jordi fita mas <jordi@tandem.blog> # Add function to edit invoices
|
||||
add_contact [schema_numerus extension_vat email extension_pg_libphonenumber extension_uri country_code tag_name contact] 2023-03-25T22:32:37Z jordi fita mas <jordi@tandem.blog> # Add function to create new contacts
|
||||
edit_contact [schema_numerus email extension_uri country_code tag_name contact extension_vat extension_pg_libphonenumber] 2023-03-25T23:20:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
|
||||
expense [schema_numerus contact company currency_code currency tag_name] 2023-04-30T13:46:36Z jordi fita mas <jordi@tandem.blog> # Add the expense relation
|
||||
|
|
|
@ -0,0 +1,172 @@
|
|||
-- Test expense
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(67);
|
||||
|
||||
set search_path to numerus, auth, public;
|
||||
|
||||
select has_table('expense');
|
||||
select has_pk('expense' );
|
||||
select table_privs_are('expense', 'guest', array []::text[]);
|
||||
select table_privs_are('expense', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
||||
select table_privs_are('expense', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
||||
select table_privs_are('expense', 'authenticator', array []::text[]);
|
||||
|
||||
select has_sequence('expense_expense_id_seq');
|
||||
select sequence_privs_are('expense_expense_id_seq', 'guest', array[]::text[]);
|
||||
select sequence_privs_are('expense_expense_id_seq', 'invoicer', array['USAGE']);
|
||||
select sequence_privs_are('expense_expense_id_seq', 'admin', array['USAGE']);
|
||||
select sequence_privs_are('expense_expense_id_seq', 'authenticator', array[]::text[]);
|
||||
|
||||
select has_column('expense', 'expense_id');
|
||||
select col_is_pk('expense', 'expense_id');
|
||||
select col_type_is('expense', 'expense_id', 'integer');
|
||||
select col_not_null('expense', 'expense_id');
|
||||
select col_has_default('expense', 'expense_id');
|
||||
select col_default_is('expense', 'expense_id', 'nextval(''expense_expense_id_seq''::regclass)');
|
||||
|
||||
select has_column('expense', 'company_id');
|
||||
select col_is_fk('expense', 'company_id');
|
||||
select fk_ok('expense', 'company_id', 'company', 'company_id');
|
||||
select col_type_is('expense', 'company_id', 'integer');
|
||||
select col_not_null('expense', 'company_id');
|
||||
select col_hasnt_default('expense', 'company_id');
|
||||
|
||||
select has_column('expense', 'slug');
|
||||
select col_is_unique('expense', 'slug');
|
||||
select col_type_is('expense', 'slug', 'uuid');
|
||||
select col_not_null('expense', 'slug');
|
||||
select col_has_default('expense', 'slug');
|
||||
select col_default_is('expense', 'slug', 'gen_random_uuid()');
|
||||
|
||||
select has_column('expense', 'contact_id');
|
||||
select col_is_fk('expense', 'contact_id');
|
||||
select fk_ok('expense', 'contact_id', 'contact', 'contact_id');
|
||||
select col_type_is('expense', 'contact_id', 'integer');
|
||||
select col_not_null('expense', 'contact_id');
|
||||
select col_hasnt_default('expense', 'contact_id');
|
||||
|
||||
select has_column('expense', 'invoice_number');
|
||||
select col_type_is('expense', 'invoice_number', 'text');
|
||||
select col_not_null('expense', 'invoice_number');
|
||||
select col_hasnt_default('expense', 'invoice_number');
|
||||
|
||||
select has_column('expense', 'invoice_date');
|
||||
select col_type_is('expense', 'invoice_date', 'date');
|
||||
select col_not_null('expense', 'invoice_date');
|
||||
select col_hasnt_default('expense', 'invoice_date');
|
||||
|
||||
select has_column('expense', 'amount');
|
||||
select col_type_is('expense', 'amount', 'integer');
|
||||
select col_not_null('expense', 'amount');
|
||||
select col_hasnt_default('expense', 'amount');
|
||||
|
||||
select has_column('expense', 'currency_code');
|
||||
select col_is_fk('expense', 'currency_code');
|
||||
select fk_ok('expense', 'currency_code', 'currency', 'currency_code');
|
||||
select col_type_is('expense', 'currency_code', 'currency_code');
|
||||
select col_not_null('expense', 'currency_code');
|
||||
select col_hasnt_default('expense', 'currency_code');
|
||||
|
||||
select has_column('expense', 'tags');
|
||||
select col_type_is('expense', 'tags', 'tag_name[]');
|
||||
select col_not_null('expense', 'tags');
|
||||
select col_has_default('expense', 'tags');
|
||||
select col_default_is('expense', 'tags', '{}');
|
||||
|
||||
select has_column('expense', 'created_at');
|
||||
select col_type_is('expense', 'created_at', 'timestamp with time zone');
|
||||
select col_not_null('expense', 'created_at');
|
||||
select col_has_default('expense', 'created_at');
|
||||
select col_default_is('expense', 'created_at', current_timestamp);
|
||||
|
||||
|
||||
set client_min_messages to warning;
|
||||
truncate expense cascade;
|
||||
truncate contact cascade;
|
||||
truncate company_user cascade;
|
||||
truncate company cascade;
|
||||
truncate payment_method 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 contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
||||
values (6, 2, 'Contact 1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
||||
, (8, 4, 'Contact 2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
||||
;
|
||||
|
||||
insert into expense (company_id, invoice_number, contact_id, invoice_date, amount, currency_code)
|
||||
values (2, 'INV020001', 6, '2011-01-11', 111, 'EUR')
|
||||
, (4, 'INV040001', 8, '2022-02-22', 222, 'EUR')
|
||||
;
|
||||
|
||||
|
||||
prepare expense_data as
|
||||
select company_id, invoice_number
|
||||
from expense
|
||||
order by company_id, invoice_number;
|
||||
|
||||
set role invoicer;
|
||||
select is_empty('expense_data', 'Should show no data when cookie is not set yet');
|
||||
reset role;
|
||||
|
||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
||||
select bag_eq(
|
||||
'expense_data',
|
||||
$$ values (2, 'INV020001')
|
||||
$$,
|
||||
'Should only list expenses of the companies where demo@tandem.blog is user of'
|
||||
);
|
||||
reset role;
|
||||
|
||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
||||
select bag_eq(
|
||||
'expense_data',
|
||||
$$ values (4, 'INV040001')
|
||||
$$,
|
||||
'Should only list expenses of the companies where admin@tandem.blog is user of'
|
||||
);
|
||||
reset role;
|
||||
|
||||
select set_cookie('not-a-cookie');
|
||||
select throws_ok(
|
||||
'expense_data',
|
||||
'42501', 'permission denied for table expense',
|
||||
'Should not allow select to guest users'
|
||||
);
|
||||
reset role;
|
||||
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
||||
|
|
@ -0,0 +1,21 @@
|
|||
-- Verify numerus:expense on pg
|
||||
|
||||
begin;
|
||||
|
||||
select expense_id
|
||||
, company_id
|
||||
, slug
|
||||
, contact_id
|
||||
, invoice_number
|
||||
, invoice_date
|
||||
, amount
|
||||
, currency_code
|
||||
, tags
|
||||
, created_at
|
||||
from numerus.expense
|
||||
where false;
|
||||
|
||||
select 1 / count(*) from pg_class where oid = 'numerus.expense'::regclass and relrowsecurity;
|
||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.expense'::regclass;
|
||||
|
||||
rollback;
|
Loading…
Reference in New Issue