Add discount_rate domain and invoice_product relation
I store again the product’s name, description, and prices, because they are bound to change, but the invoice should remain the same always. That makes me wonder if i should do the same for seller’s and buyer’s data, but that should be a different commit. I’ve added the discount_rate domain because then i can test it independently of the invoice_product relation, moreover i am sure i will need it for simplified invoices too.
This commit is contained in:
parent
96cfee6f56
commit
6bf51d5eeb
|
@ -0,0 +1,14 @@
|
|||
-- Deploy numerus:discount_rate to pg
|
||||
-- requires: schema_numerus
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create domain discount_rate as numeric
|
||||
check (VALUE >= 0 and VALUE <= 1);
|
||||
|
||||
comment on domain discount_rate is
|
||||
'A rate for discount in the range [0, 1]';
|
||||
|
||||
commit;
|
|
@ -0,0 +1,39 @@
|
|||
-- Deploy numerus:invoice_product to pg
|
||||
-- requires: schema_numerus
|
||||
-- requires: invoice
|
||||
-- requires: discount_rate
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create table invoice_product (
|
||||
invoice_product_id serial primary key,
|
||||
invoice_id integer not null references invoice,
|
||||
product_id integer not null references product,
|
||||
name text not null,
|
||||
description text not null,
|
||||
price integer not null,
|
||||
quantity integer not null,
|
||||
discount_rate discount_rate not null default 0.0
|
||||
);
|
||||
|
||||
grant select, insert, update, delete on table invoice_product to invoicer;
|
||||
grant select, insert, update, delete on table invoice_product to admin;
|
||||
|
||||
grant usage on sequence invoice_product_invoice_product_id_seq to invoicer;
|
||||
grant usage on sequence invoice_product_invoice_product_id_seq to admin;
|
||||
|
||||
alter table invoice_product enable row level security;
|
||||
|
||||
create policy company_policy
|
||||
on invoice_product
|
||||
using (
|
||||
exists(
|
||||
select 1
|
||||
from invoice
|
||||
where invoice.invoice_id = invoice_product.invoice_id
|
||||
)
|
||||
);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:discount_rate from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop domain if exists numerus.discount_rate;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:invoice_product from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop table if exists numerus.invoice_product;
|
||||
|
||||
commit;
|
|
@ -47,3 +47,5 @@ invoice_status_i18n [schema_numerus invoice_status language] 2023-02-07T14:56:18
|
|||
available_invoice_status [schema_numerus invoice_status invoice_status_i18n] 2023-02-07T15:07:06Z jordi fita mas <jordi@tandem.blog> # Add the list of available invoice status
|
||||
product_tax [schema_numerus product tax] 2023-02-08T11:36:49Z jordi fita mas <jordi@tandem.blog> # Add relation of product taxes
|
||||
invoice [schema_numerus company contact invoice_status currency] 2023-02-09T09:52:21Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice
|
||||
discount_rate [schema_numerus] 2023-02-10T17:22:40Z jordi fita mas <jordi@tandem.blog> # Add domain for discount rates
|
||||
invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice product
|
||||
|
|
|
@ -0,0 +1,34 @@
|
|||
-- Test discount_rate
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(7);
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
select has_domain('discount_rate');
|
||||
select domain_type_is('discount_rate', 'numeric');
|
||||
|
||||
select lives_ok($$ select 1::discount_rate $$, 'Should be able to cast valid 100 % to discount rate');
|
||||
select lives_ok($$ select 0.21::discount_rate $$, 'Should be able to cast valid positive decimals to discount rate');
|
||||
select lives_ok($$ select 0::discount_rate $$, 'Should be able to cast valid zero to discount rate');
|
||||
|
||||
select throws_ok(
|
||||
$$ SELECT (-0.01)::discount_rate $$,
|
||||
23514, null,
|
||||
'Should reject negative discount rate'
|
||||
);
|
||||
|
||||
select throws_ok(
|
||||
$$ SELECT 1.01::discount_rate $$,
|
||||
23514, null,
|
||||
'Should not allow past the 100 % discount'
|
||||
);
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,158 @@
|
|||
-- Test invoice_product
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(54);
|
||||
|
||||
set search_path to numerus, auth, public;
|
||||
|
||||
select has_table('invoice_product');
|
||||
select has_pk('invoice_product' );
|
||||
select table_privs_are('invoice_product', 'guest', array []::text[]);
|
||||
select table_privs_are('invoice_product', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
||||
select table_privs_are('invoice_product', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
|
||||
select table_privs_are('invoice_product', 'authenticator', array []::text[]);
|
||||
|
||||
select has_sequence('invoice_product_invoice_product_id_seq');
|
||||
select sequence_privs_are('invoice_product_invoice_product_id_seq', 'guest', array[]::text[]);
|
||||
select sequence_privs_are('invoice_product_invoice_product_id_seq', 'invoicer', array['USAGE']);
|
||||
select sequence_privs_are('invoice_product_invoice_product_id_seq', 'admin', array['USAGE']);
|
||||
select sequence_privs_are('invoice_product_invoice_product_id_seq', 'authenticator', array[]::text[]);
|
||||
|
||||
select has_column('invoice_product', 'invoice_product_id');
|
||||
select col_is_pk('invoice_product', 'invoice_product_id');
|
||||
select col_type_is('invoice_product', 'invoice_product_id', 'integer');
|
||||
select col_not_null('invoice_product', 'invoice_product_id');
|
||||
select col_has_default('invoice_product', 'invoice_product_id');
|
||||
select col_default_is('invoice_product', 'invoice_product_id', 'nextval(''invoice_product_invoice_product_id_seq''::regclass)');
|
||||
|
||||
select has_column('invoice_product', 'invoice_id');
|
||||
select col_is_fk('invoice_product', 'invoice_id');
|
||||
select fk_ok('invoice_product', 'invoice_id', 'invoice', 'invoice_id');
|
||||
select col_type_is('invoice_product', 'invoice_id', 'integer');
|
||||
select col_not_null('invoice_product', 'invoice_id');
|
||||
select col_hasnt_default('invoice_product', 'invoice_id');
|
||||
|
||||
select has_column('invoice_product', 'product_id');
|
||||
select col_is_fk('invoice_product', 'product_id');
|
||||
select fk_ok('invoice_product', 'product_id', 'product', 'product_id');
|
||||
select col_type_is('invoice_product', 'product_id', 'integer');
|
||||
select col_not_null('invoice_product', 'product_id');
|
||||
select col_hasnt_default('invoice_product', 'product_id');
|
||||
|
||||
select has_column('invoice_product', 'name');
|
||||
select col_type_is('invoice_product', 'name', 'text');
|
||||
select col_not_null('invoice_product', 'name');
|
||||
select col_hasnt_default('invoice_product', 'name');
|
||||
|
||||
select has_column('invoice_product', 'description');
|
||||
select col_type_is('invoice_product', 'description', 'text');
|
||||
select col_not_null('invoice_product', 'description');
|
||||
select col_hasnt_default('invoice_product', 'description');
|
||||
|
||||
select has_column('invoice_product', 'price');
|
||||
select col_type_is('invoice_product', 'price', 'integer');
|
||||
select col_not_null('invoice_product', 'price');
|
||||
select col_hasnt_default('invoice_product', 'price');
|
||||
|
||||
select has_column('invoice_product', 'quantity');
|
||||
select col_type_is('invoice_product', 'quantity', 'integer');
|
||||
select col_not_null('invoice_product', 'quantity');
|
||||
select col_hasnt_default('invoice_product', 'quantity');
|
||||
|
||||
select has_column('invoice_product', 'discount_rate');
|
||||
select col_type_is('invoice_product', 'discount_rate', 'discount_rate');
|
||||
select col_not_null('invoice_product', 'discount_rate');
|
||||
select col_has_default('invoice_product', 'discount_rate');
|
||||
select col_default_is('invoice_product', 'discount_rate', '0.0');
|
||||
|
||||
|
||||
set client_min_messages to warning;
|
||||
truncate invoice_product cascade;
|
||||
truncate invoice cascade;
|
||||
truncate product cascade;
|
||||
truncate contact 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, 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')
|
||||
;
|
||||
|
||||
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code)
|
||||
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR')
|
||||
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD')
|
||||
;
|
||||
|
||||
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 invoice (invoice_id, company_id, invoice_number, contact_id, currency_code)
|
||||
values (10, 2, 'INV020001', 6, 'EUR')
|
||||
, (12, 4, 'INV040001', 8, 'EUR')
|
||||
;
|
||||
|
||||
insert into product (product_id, company_id, name, description, price)
|
||||
values (14, 2, 'Product 1', 'Description 1', 1200)
|
||||
, (16, 4, 'Product 2', 'Description 2', 2400)
|
||||
;
|
||||
|
||||
insert into invoice_product (invoice_id, product_id, name, description, price, quantity)
|
||||
values (10, 14, 'product 1', 'description 1', 1212, 1)
|
||||
, (12, 16, 'product 2', 'description 2', 2424, 2)
|
||||
;
|
||||
|
||||
|
||||
prepare invoice_product_data as
|
||||
select invoice_id, product_id, name, price, quantity
|
||||
from invoice_product
|
||||
order by invoice_id, product_id;
|
||||
|
||||
set role invoicer;
|
||||
select is_empty('invoice_product_data', 'Should show no data when cookie is not set yet');
|
||||
reset role;
|
||||
|
||||
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
|
||||
select bag_eq(
|
||||
'invoice_product_data',
|
||||
$$ values (10, 14, 'product 1', 1212, 1)
|
||||
$$,
|
||||
'Should only list products of invoices of the companies where demo@tandem.blog is user of'
|
||||
);
|
||||
reset role;
|
||||
|
||||
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
|
||||
select bag_eq(
|
||||
'invoice_product_data',
|
||||
$$ values (12, 16, 'product 2', 2424, 2)
|
||||
$$,
|
||||
'Should only list products of invoices of the companies where admin@tandem.blog is user of'
|
||||
);
|
||||
reset role;
|
||||
|
||||
select set_cookie('not-a-cookie');
|
||||
select throws_ok(
|
||||
'invoice_product_data',
|
||||
'42501', 'permission denied for table invoice_product',
|
||||
'Should not allow select to guest users'
|
||||
);
|
||||
reset role;
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
||||
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:discount_rate on pg
|
||||
|
||||
begin;
|
||||
|
||||
select pg_catalog.has_type_privilege('numerus.discount_rate', 'usage');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,19 @@
|
|||
-- Verify numerus:invoice_product on pg
|
||||
|
||||
begin;
|
||||
|
||||
select invoice_product_id
|
||||
, invoice_id
|
||||
, product_id
|
||||
, name
|
||||
, description
|
||||
, price
|
||||
, quantity
|
||||
, discount_rate
|
||||
from numerus.invoice_product
|
||||
where false;
|
||||
|
||||
select 1 / count(*) from pg_class where oid = 'numerus.invoice_product'::regclass and relrowsecurity;
|
||||
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.invoice_product'::regclass;
|
||||
|
||||
rollback;
|
Loading…
Reference in New Issue