Add relations for sales quotations and their products

They are mostly the same as invoices, but the contact and payment method
are optional, thus, like other optionals fields, i created relations to
link these that have payment method or contact, to avoid NULL columns in
quote.

Still missing functions to add and edit quotations, and views to compute
their tax and total amount.
This commit is contained in:
jordi fita mas 2023-06-06 21:08:31 +02:00
parent d7a256804f
commit 35b12f7ea4
36 changed files with 1130 additions and 0 deletions

View File

@ -0,0 +1,28 @@
-- Deploy numerus:available_quote_status to pg
-- requires: schema_numerus
-- requires: quote_status
-- requires: quote_status_i18n
begin;
set search_path to numerus;
insert into quote_status (quote_status, name)
values ('created', 'Created')
, ('sent', 'Sent')
, ('accepted', 'Accepted')
, ('rejected', 'Rejected')
;
insert into quote_status_i18n (quote_status, lang_tag, name)
values ('created', 'ca', 'Creat')
, ('sent', 'ca', 'Enviat')
, ('accepted', 'ca', 'Acceptat')
, ('rejected', 'ca', 'Rebutjat')
, ('created', 'es', 'Creado')
, ('sent', 'es', 'Enviado')
, ('accepted', 'es', 'Aceptado')
, ('rejected', 'es', 'Rechazado')
;
commit;

48
deploy/quote.sql Normal file
View File

@ -0,0 +1,48 @@
-- Deploy numerus:quote to pg
-- requires: roles
-- requires: schema_numerus
-- requires: company
-- requires: quote_status
-- requires: currency
-- requires: tag_name
begin;
set search_path to numerus, public;
create table quote (
quote_id serial primary key,
company_id integer not null references company,
slug uuid not null unique default gen_random_uuid(),
quote_number text not null constraint quote_number_not_empty check(length(trim(quote_number)) > 1),
quote_date date not null default current_date,
quote_status text not null default 'created' references quote_status,
terms_and_conditions text not null default '',
notes text not null default '',
tags tag_name[] not null default '{}',
currency_code text not null references currency,
created_at timestamptz not null default current_timestamp
);
create index on quote using gin (tags);
grant select, insert, update, delete on table quote to invoicer;
grant select, insert, update, delete on table quote to admin;
grant usage on sequence quote_quote_id_seq to invoicer;
grant usage on sequence quote_quote_id_seq to admin;
alter table quote enable row level security;
create policy company_policy
on quote
using (
exists(
select 1
from company_user
join user_profile using (user_id)
where company_user.company_id = quote.company_id
)
);
commit;

19
deploy/quote_contact.sql Normal file
View File

@ -0,0 +1,19 @@
-- Deploy numerus:quote_contact to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote
-- requires: contact
begin;
set search_path to numerus, public;
create table quote_contact (
quote_id integer primary key references quote,
contact_id integer not null references contact
);
grant select, insert, update, delete on table quote_contact to invoicer;
grant select, insert, update, delete on table quote_contact to admin;
commit;

View File

@ -0,0 +1,19 @@
-- Deploy numerus:quote_payment_method to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote
-- requires: payment_method
begin;
set search_path to numerus, public;
create table quote_payment_method (
quote_id integer not null primary key references quote,
payment_method_id integer not null references payment_method
);
grant select, insert, update, delete on table quote_payment_method to invoicer;
grant select, insert, update, delete on table quote_payment_method to admin;
commit;

39
deploy/quote_product.sql Normal file
View File

@ -0,0 +1,39 @@
-- Deploy numerus:quote_product to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote
-- requires: discount_rate
begin;
set search_path to numerus, public;
create table quote_product (
quote_product_id serial primary key,
quote_id integer not null references quote,
name text not null constraint name_not_empty check(length(trim(name)) > 0),
description text not null default '',
price integer not null,
quantity integer not null default 1,
discount_rate discount_rate not null default 0.0
);
grant select, insert, update, delete on table quote_product to invoicer;
grant select, insert, update, delete on table quote_product to admin;
grant usage on sequence quote_product_quote_product_id_seq to invoicer;
grant usage on sequence quote_product_quote_product_id_seq to admin;
alter table quote_product enable row level security;
create policy company_policy
on quote_product
using (
exists(
select 1
from quote
where quote.quote_id = quote_product.quote_id
)
);
commit;

View File

@ -0,0 +1,19 @@
-- Deploy numerus:quote_product_product to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote_product
-- requires: product
begin;
set search_path to numerus, public;
create table quote_product_product (
quote_product_id integer primary key references quote_product,
product_id integer not null references product
);
grant select, insert, update, delete on table quote_product_product to invoicer;
grant select, insert, update, delete on table quote_product_product to admin;
commit;

View File

@ -0,0 +1,34 @@
-- Deploy numerus:quote_product_tax to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote_product
-- requires: tax
-- requires: tax_rate
begin;
set search_path to numerus, public;
create table quote_product_tax (
quote_product_id integer not null references quote_product,
tax_id integer not null references tax,
tax_rate tax_rate not null,
primary key (quote_product_id, tax_id)
);
grant select, insert, update, delete on table quote_product_tax to invoicer;
grant select, insert, update, delete on table quote_product_tax to admin;
alter table quote_product_tax enable row level security;
create policy company_policy
on quote_product_tax
using (
exists(
select 1
from quote_product
where quote_product.quote_product_id = quote_product_tax.quote_product_id
)
);
commit;

17
deploy/quote_status.sql Normal file
View File

@ -0,0 +1,17 @@
-- Deploy numerus:quote_status to pg
-- requires: roles
-- requires: schema_numerus
begin;
set search_path to numerus, public;
create table quote_status (
quote_status text primary key,
name text not null
);
grant select on table quote_status to invoicer;
grant select on table quote_status to admin;
commit;

View File

@ -0,0 +1,21 @@
-- Deploy numerus:quote_status_i18n to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote_status
-- requires: language
begin;
set search_path to numerus, public;
create table quote_status_i18n (
quote_status text not null references quote_status,
lang_tag text not null references language,
name text not null,
primary key (quote_status, lang_tag)
);
grant select on table quote_status_i18n to invoicer;
grant select on table quote_status_i18n to admin;
commit;

View File

@ -0,0 +1,10 @@
-- Revert numerus:available_quote_status from pg
begin;
set search_path to numerus;
delete from quote_status_i18n;
delete from quote_status;
commit;

7
revert/quote.sql Normal file
View File

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

7
revert/quote_contact.sql Normal file
View File

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

View File

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

7
revert/quote_product.sql Normal file
View File

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

View File

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

View File

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

7
revert/quote_status.sql Normal file
View File

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

View File

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

View File

@ -77,3 +77,12 @@ edit_expense [schema_numerus expense currency parse_price tax tag_name] 2023-05-
expense_attachment [schema_numerus expense] 2023-05-13T19:11:21Z jordi fita mas <jordi@tandem.blog> # Add relation of expense attachments
attach_to_expense [schema_numerus expense expense_attachment] 2023-05-15T10:18:31Z jordi fita mas <jordi@tandem.blog> # Add function to attach documents to expenses
expense_tax_amount [schema_numerus expense expense_tax] 2023-05-18T10:15:40Z jordi fita mas <jordi@tandem.blog> # Add vier for expense tax amount
quote_status [roles schema_numerus] 2023-06-06T17:05:53Z jordi fita mas <jordi@tandem.blog> # Add relation for quote status
quote_status_i18n [roles schema_numerus quote_status language] 2023-06-06T17:13:50Z jordi fita mas <jordi@tandem.blog> # Add relation for quote status translatable texts
available_quote_status [schema_numerus quote_status quote_status_i18n] 2023-06-06T17:18:48Z jordi fita mas <jordi@tandem.blog> # Add the list of available quote status
quote [roles schema_numerus company quote_status currency tag_name] 2023-06-06T17:46:27Z jordi fita mas <jordi@tandem.blog> # Add relation for sales quotations
quote_contact [roles schema_numerus quote contact] 2023-06-06T18:17:50Z jordi fita mas <jordi@tandem.blog> # Add relation of quote contact
quote_product [roles schema_numerus quote discount_rate] 2023-06-06T18:25:05Z jordi fita mas <jordi@tandem.blog> # Add relation for quote products
quote_product_product [roles schema_numerus quote_product product] 2023-06-06T18:38:26Z jordi fita mas <jordi@tandem.blog> # Add relation of quote products and registered products
quote_product_tax [roles schema_numerus quote_product tax tax_rate] 2023-06-06T18:46:33Z jordi fita mas <jordi@tandem.blog> # Add relation of quotation product tax
quote_payment_method [roles schema_numerus quote payment_method] 2023-06-06T18:59:12Z jordi fita mas <jordi@tandem.blog> # Add relation for the payment method of quotes

183
test/quote.sql Normal file
View File

@ -0,0 +1,183 @@
-- Test quote
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(76);
set search_path to numerus, auth, public;
select has_table('quote');
select has_pk('quote' );
select table_privs_are('quote', 'guest', array []::text[]);
select table_privs_are('quote', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote', 'authenticator', array []::text[]);
select has_sequence('quote_quote_id_seq');
select sequence_privs_are('quote_quote_id_seq', 'guest', array[]::text[]);
select sequence_privs_are('quote_quote_id_seq', 'invoicer', array['USAGE']);
select sequence_privs_are('quote_quote_id_seq', 'admin', array['USAGE']);
select sequence_privs_are('quote_quote_id_seq', 'authenticator', array[]::text[]);
select has_column('quote', 'quote_id');
select col_is_pk('quote', 'quote_id');
select col_type_is('quote', 'quote_id', 'integer');
select col_not_null('quote', 'quote_id');
select col_has_default('quote', 'quote_id');
select col_default_is('quote', 'quote_id', 'nextval(''quote_quote_id_seq''::regclass)');
select has_column('quote', 'company_id');
select col_is_fk('quote', 'company_id');
select fk_ok('quote', 'company_id', 'company', 'company_id');
select col_type_is('quote', 'company_id', 'integer');
select col_not_null('quote', 'company_id');
select col_hasnt_default('quote', 'company_id');
select has_column('quote', 'slug');
select col_is_unique('quote', 'slug');
select col_type_is('quote', 'slug', 'uuid');
select col_not_null('quote', 'slug');
select col_has_default('quote', 'slug');
select col_default_is('quote', 'slug', 'gen_random_uuid()');
select has_column('quote', 'quote_number');
select col_type_is('quote', 'quote_number', 'text');
select col_not_null('quote', 'quote_number');
select col_hasnt_default('quote', 'quote_number');
select has_column('quote', 'quote_date');
select col_type_is('quote', 'quote_date', 'date');
select col_not_null('quote', 'quote_date');
select col_has_default('quote', 'quote_date');
select col_default_is('quote', 'quote_date', current_date);
select has_column('quote', 'quote_status');
select col_is_fk('quote', 'quote_status');
select fk_ok('quote', 'quote_status', 'quote_status', 'quote_status');
select col_type_is('quote', 'quote_status', 'text');
select col_not_null('quote', 'quote_status');
select col_has_default('quote', 'quote_status');
select col_default_is('quote', 'quote_status', 'created');
select has_column('quote', 'terms_and_conditions');
select col_type_is('quote', 'terms_and_conditions', 'text');
select col_not_null('quote', 'terms_and_conditions');
select col_has_default('quote', 'terms_and_conditions');
select col_default_is('quote', 'terms_and_conditions', '');
select has_column('quote', 'notes');
select col_type_is('quote', 'notes', 'text');
select col_not_null('quote', 'notes');
select col_has_default('quote', 'notes');
select col_default_is('quote', 'notes', '');
select has_column('quote', 'tags');
select col_type_is('quote', 'tags', 'tag_name[]');
select col_not_null('quote', 'tags');
select col_has_default('quote', 'tags');
select col_default_is('quote', 'tags', '{}');
select has_column('quote', 'currency_code');
select col_is_fk('quote', 'currency_code');
select fk_ok('quote', 'currency_code', 'currency', 'currency_code');
select col_type_is('quote', 'currency_code', 'text');
select col_not_null('quote', 'currency_code');
select col_hasnt_default('quote', 'currency_code');
select has_column('quote', 'created_at');
select col_type_is('quote', 'created_at', 'timestamp with time zone');
select col_not_null('quote', 'created_at');
select col_has_default('quote', 'created_at');
select col_default_is('quote', 'created_at', current_timestamp);
set client_min_messages to warning;
truncate quote 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 quote (company_id, quote_number, currency_code)
values (2, 'QUO020001', 'EUR')
, (4, 'QUO040001', 'EUR')
;
prepare quote_data as
select company_id, quote_number
from quote
order by company_id, quote_number;
set role invoicer;
select is_empty('quote_data', 'Should show no data when cookie is not set yet');
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select bag_eq(
'quote_data',
$$ values (2, 'QUO020001')
$$,
'Should only list quotations from the companies where demo@tandem.blog is user of'
);
reset role;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
select bag_eq(
'quote_data',
$$ values (4, 'QUO040001')
$$,
'Should only list quotations from the companies where admin@tandem.blog is user of'
);
reset role;
select set_cookie('not-a-cookie');
select throws_ok(
'quote_data',
'42501', 'permission denied for table quote',
'Should not allow select to guest users'
);
reset role;
select throws_ok( $$
insert into quote (company_id, quote_number, currency_code)
values (2, ' ', 'EUR')
$$,
'23514', 'new row for relation "quote" violates check constraint "quote_number_not_empty"',
'Should not allow quotes with a blank number'
);
select *
from finish();
rollback;

39
test/quote_contact.sql Normal file
View File

@ -0,0 +1,39 @@
-- Test quote_contact
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(19);
set search_path to numerus, public;
select has_table('quote_contact');
select has_pk('quote_contact' );
select table_privs_are('quote_contact', 'guest', array []::text[]);
select table_privs_are('quote_contact', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_contact', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_contact', 'authenticator', array []::text[]);
select has_column('quote_contact', 'quote_id');
select col_is_pk('quote_contact', 'quote_id');
select col_is_fk('quote_contact', 'quote_id');
select fk_ok('quote_contact', 'quote_id', 'quote', 'quote_id');
select col_type_is('quote_contact', 'quote_id', 'integer');
select col_not_null('quote_contact', 'quote_id');
select col_hasnt_default('quote_contact', 'quote_id');
select has_column('quote_contact', 'contact_id');
select col_is_fk('quote_contact', 'contact_id');
select fk_ok('quote_contact', 'contact_id', 'contact', 'contact_id');
select col_type_is('quote_contact', 'contact_id', 'integer');
select col_not_null('quote_contact', 'contact_id');
select col_hasnt_default('quote_contact', 'contact_id');
select *
from finish();
rollback;

View File

@ -0,0 +1,39 @@
-- Test quote_payment_method
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(19);
set search_path to numerus, public;
select has_table('quote_payment_method');
select has_pk('quote_payment_method' );
select table_privs_are('quote_payment_method', 'guest', array []::text[]);
select table_privs_are('quote_payment_method', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_payment_method', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_payment_method', 'authenticator', array []::text[]);
select has_column('quote_payment_method', 'quote_id');
select col_is_pk('quote_payment_method', 'quote_id');
select col_is_fk('quote_payment_method', 'quote_id');
select fk_ok('quote_payment_method', 'quote_id', 'quote', 'quote_id');
select col_type_is('quote_payment_method', 'quote_id', 'integer');
select col_not_null('quote_payment_method', 'quote_id');
select col_hasnt_default('quote_payment_method', 'quote_id');
select has_column('quote_payment_method', 'payment_method_id');
select col_is_fk('quote_payment_method', 'payment_method_id');
select fk_ok('quote_payment_method', 'payment_method_id', 'payment_method', 'payment_method_id');
select col_type_is('quote_payment_method', 'payment_method_id', 'integer');
select col_not_null('quote_payment_method', 'payment_method_id');
select col_hasnt_default('quote_payment_method', 'payment_method_id');
select *
from finish();
rollback;

161
test/quote_product.sql Normal file
View File

@ -0,0 +1,161 @@
-- Test quote_product
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(51);
set search_path to numerus, auth, public;
select has_table('quote_product');
select has_pk('quote_product' );
select table_privs_are('quote_product', 'guest', array []::text[]);
select table_privs_are('quote_product', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product', 'authenticator', array []::text[]);
select has_sequence('quote_product_quote_product_id_seq');
select sequence_privs_are('quote_product_quote_product_id_seq', 'guest', array[]::text[]);
select sequence_privs_are('quote_product_quote_product_id_seq', 'invoicer', array['USAGE']);
select sequence_privs_are('quote_product_quote_product_id_seq', 'admin', array['USAGE']);
select sequence_privs_are('quote_product_quote_product_id_seq', 'authenticator', array[]::text[]);
select has_column('quote_product', 'quote_product_id');
select col_is_pk('quote_product', 'quote_product_id');
select col_type_is('quote_product', 'quote_product_id', 'integer');
select col_not_null('quote_product', 'quote_product_id');
select col_has_default('quote_product', 'quote_product_id');
select col_default_is('quote_product', 'quote_product_id', 'nextval(''quote_product_quote_product_id_seq''::regclass)');
select has_column('quote_product', 'quote_id');
select col_is_fk('quote_product', 'quote_id');
select fk_ok('quote_product', 'quote_id', 'quote', 'quote_id');
select col_type_is('quote_product', 'quote_id', 'integer');
select col_not_null('quote_product', 'quote_id');
select col_hasnt_default('quote_product', 'quote_id');
select has_column('quote_product', 'name');
select col_type_is('quote_product', 'name', 'text');
select col_not_null('quote_product', 'name');
select col_hasnt_default('quote_product', 'name');
select has_column('quote_product', 'description');
select col_type_is('quote_product', 'description', 'text');
select col_not_null('quote_product', 'description');
select col_has_default('quote_product', 'description');
select col_default_is('quote_product', 'description', '');
select has_column('quote_product', 'price');
select col_type_is('quote_product', 'price', 'integer');
select col_not_null('quote_product', 'price');
select col_hasnt_default('quote_product', 'price');
select has_column('quote_product', 'quantity');
select col_type_is('quote_product', 'quantity', 'integer');
select col_not_null('quote_product', 'quantity');
select col_has_default('quote_product', 'quantity');
select col_default_is('quote_product', 'quantity', 1);
select has_column('quote_product', 'discount_rate');
select col_type_is('quote_product', 'discount_rate', 'discount_rate');
select col_not_null('quote_product', 'discount_rate');
select col_has_default('quote_product', 'discount_rate');
select col_default_is('quote_product', 'discount_rate', '0.0');
set client_min_messages to warning;
truncate quote_product cascade;
truncate quote 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 quote (quote_id, company_id, quote_number, currency_code)
values (10, 2, 'QUO020001', 'EUR')
, (12, 4, 'QUO040001', 'EUR')
;
insert into quote_product (quote_id, name, description, price, quantity)
values (10, 'product 1', 'description 1', 1212, 1)
, (12, 'product 2', 'description 2', 2424, 2)
;
prepare quote_product_data as
select quote_id, name, price, quantity
from quote_product
order by quote_id;
set role invoicer;
select is_empty('quote_product_data', 'Should show no data when cookie is not set yet');
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select bag_eq(
'quote_product_data',
$$ values (10, 'product 1', 1212, 1)
$$,
'Should only list products of quotes from the companies where demo@tandem.blog is user of'
);
reset role;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
select bag_eq(
'quote_product_data',
$$ values (12, 'product 2', 2424, 2)
$$,
'Should only list products of quotes from the companies where admin@tandem.blog is user of'
);
reset role;
select set_cookie('not-a-cookie');
select throws_ok(
'quote_product_data',
'42501', 'permission denied for table quote_product',
'Should not allow select to guest users'
);
reset role;
select throws_ok( $$
insert into quote_product (quote_id, name, description, price, quantity)
values (10, ' ', '', 1212, 1)
$$,
'23514', 'new row for relation "quote_product" violates check constraint "name_not_empty"',
'Should not allow quote products with blank name'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,39 @@
-- Test quote_product_product
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(19);
set search_path to numerus, public;
select has_table('quote_product_product');
select has_pk('quote_product_product' );
select table_privs_are('quote_product_product', 'guest', array []::text[]);
select table_privs_are('quote_product_product', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product_product', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product_product', 'authenticator', array []::text[]);
select has_column('quote_product_product', 'quote_product_id');
select col_is_pk('quote_product_product', 'quote_product_id');
select col_is_fk('quote_product_product', 'quote_product_id');
select fk_ok('quote_product_product', 'quote_product_id', 'quote_product', 'quote_product_id');
select col_type_is('quote_product_product', 'quote_product_id', 'integer');
select col_not_null('quote_product_product', 'quote_product_id');
select col_hasnt_default('quote_product_product', 'quote_product_id');
select has_column('quote_product_product', 'product_id');
select col_is_fk('quote_product_product', 'product_id');
select fk_ok('quote_product_product', 'product_id', 'product', 'product_id');
select col_type_is('quote_product_product', 'product_id', 'integer');
select col_not_null('quote_product_product', 'product_id');
select col_hasnt_default('quote_product_product', 'product_id');
select *
from finish();
rollback;

145
test/quote_product_tax.sql Normal file
View File

@ -0,0 +1,145 @@
-- Test quote_product_tax
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(27);
set search_path to numerus, auth, public;
select has_table('quote_product_tax');
select has_pk('quote_product_tax' );
select col_is_pk('quote_product_tax', array['quote_product_id', 'tax_id']);
select table_privs_are('quote_product_tax', 'guest', array []::text[]);
select table_privs_are('quote_product_tax', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product_tax', 'admin', array ['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('quote_product_tax', 'authenticator', array []::text[]);
select has_column('quote_product_tax', 'quote_product_id');
select col_is_fk('quote_product_tax', 'quote_product_id');
select fk_ok('quote_product_tax', 'quote_product_id', 'quote_product', 'quote_product_id');
select col_type_is('quote_product_tax', 'quote_product_id', 'integer');
select col_not_null('quote_product_tax', 'quote_product_id');
select col_hasnt_default('quote_product_tax', 'quote_product_id');
select has_column('quote_product_tax', 'tax_id');
select col_is_fk('quote_product_tax', 'tax_id');
select fk_ok('quote_product_tax', 'tax_id', 'tax', 'tax_id');
select col_type_is('quote_product_tax', 'tax_id', 'integer');
select col_not_null('quote_product_tax', 'tax_id');
select col_hasnt_default('quote_product_tax', 'tax_id');
select has_column('quote_product_tax', 'tax_rate');
select col_type_is('quote_product_tax', 'tax_rate', 'tax_rate');
select col_not_null('quote_product_tax', 'tax_rate');
select col_hasnt_default('quote_product_tax', 'tax_rate');
set client_min_messages to warning;
truncate quote_product_tax cascade;
truncate quote_product cascade;
truncate invoice cascade;
truncate tax cascade;
truncate tax_class 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 quote (quote_id, company_id, quote_number, currency_code)
values (11, 2, 'QUO001', 'EUR')
, (12, 4, 'QUO002', 'EUR')
;
insert into quote_product (quote_product_id, quote_id, name, price)
values (13, 11, 'Product 1', 1200)
, (14, 12, 'Product 2', 2400)
;
insert into quote_product_tax (quote_product_id, tax_id, tax_rate)
values (13, 3, 0.10)
, (14, 6, -0.15)
;
prepare product_tax_data as
select quote_product_id, tax_id
from quote_product_tax
order by quote_product_id, tax_id;
set role invoicer;
select is_empty('product_tax_data', 'Should show no data when cookie is not set yet');
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select bag_eq(
'product_tax_data',
$$ values (13, 3)
$$,
'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(
'product_tax_data',
$$ values (14, 6)
$$,
'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(
'product_tax_data',
'42501', 'permission denied for table quote_product_tax',
'Should not allow select to guest users'
);
reset role;
select *
from finish();
select *
from finish();
rollback;

35
test/quote_status.sql Normal file
View File

@ -0,0 +1,35 @@
-- Test quote_status
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(15);
set search_path to numerus, public;
select has_table('quote_status');
select has_pk('quote_status' );
select table_privs_are('quote_status', 'guest', array []::text[]);
select table_privs_are('quote_status', 'invoicer', array ['SELECT']);
select table_privs_are('quote_status', 'admin', array ['SELECT']);
select table_privs_are('quote_status', 'authenticator', array []::text[]);
select has_column('quote_status', 'quote_status');
select col_is_pk('quote_status', 'quote_status');
select col_type_is('quote_status', 'quote_status', 'text');
select col_not_null('quote_status', 'quote_status');
select col_hasnt_default('quote_status', 'quote_status');
select has_column('quote_status', 'name');
select col_type_is('quote_status', 'name', 'text');
select col_not_null('quote_status', 'name');
select col_hasnt_default('quote_status', 'name');
select *
from finish();
rollback;

View File

@ -0,0 +1,44 @@
-- Test quote_status_i18n
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(23);
set search_path to numerus, public;
select has_table('quote_status_i18n');
select has_pk('quote_status_i18n' );
select col_is_pk('quote_status_i18n', array['quote_status', 'lang_tag']);
select table_privs_are('quote_status_i18n', 'guest', array []::text[]);
select table_privs_are('quote_status_i18n', 'invoicer', array ['SELECT']);
select table_privs_are('quote_status_i18n', 'admin', array ['SELECT']);
select table_privs_are('quote_status_i18n', 'authenticator', array []::text[]);
select has_column('quote_status_i18n', 'quote_status');
select col_is_fk('quote_status_i18n', 'quote_status');
select fk_ok('quote_status_i18n', 'quote_status', 'quote_status', 'quote_status');
select col_type_is('quote_status_i18n', 'quote_status', 'text');
select col_not_null('quote_status_i18n', 'quote_status');
select col_hasnt_default('quote_status_i18n', 'quote_status');
select has_column('quote_status_i18n', 'lang_tag');
select col_is_fk('quote_status_i18n', 'lang_tag');
select fk_ok('quote_status_i18n', 'lang_tag', 'language', 'lang_tag');
select col_type_is('quote_status_i18n', 'lang_tag', 'text');
select col_not_null('quote_status_i18n', 'lang_tag');
select col_hasnt_default('quote_status_i18n', 'lang_tag');
select has_column('quote_status_i18n', 'name');
select col_type_is('quote_status_i18n', 'name', 'text');
select col_not_null('quote_status_i18n', 'name');
select col_hasnt_default('quote_status_i18n', 'name');
select *
from finish();
rollback;

View File

@ -0,0 +1,21 @@
-- Verify numerus:available_quote_status on pg
begin;
set search_path to numerus;
select 1 / count(*) from quote_status where quote_status = 'created' and name ='Created';
select 1 / count(*) from quote_status where quote_status = 'sent' and name ='Sent';
select 1 / count(*) from quote_status where quote_status = 'accepted' and name ='Accepted';
select 1 / count(*) from quote_status where quote_status = 'rejected' and name ='Rejected';
select 1 / count(*) from quote_status_i18n where quote_status = 'created' and name ='Creat' and lang_tag = 'ca';
select 1 / count(*) from quote_status_i18n where quote_status = 'created' and name ='Creado' and lang_tag = 'es';
select 1 / count(*) from quote_status_i18n where quote_status = 'sent' and name ='Enviat' and lang_tag= 'ca';
select 1 / count(*) from quote_status_i18n where quote_status = 'sent' and name ='Enviado' and lang_tag= 'es';
select 1 / count(*) from quote_status_i18n where quote_status = 'accepted' and name ='Acceptat' and lang_tag= 'ca';
select 1 / count(*) from quote_status_i18n where quote_status = 'accepted' and name ='Aceptado' and lang_tag= 'es';
select 1 / count(*) from quote_status_i18n where quote_status = 'rejected' and name ='Rebutjat' and lang_tag= 'ca';
select 1 / count(*) from quote_status_i18n where quote_status = 'rejected' and name ='Rechazado' and lang_tag= 'es';
rollback;

22
verify/quote.sql Normal file
View File

@ -0,0 +1,22 @@
-- Verify numerus:quote on pg
begin;
select quote_id
, company_id
, slug
, quote_number
, quote_date
, quote_status
, terms_and_conditions
, notes
, tags
, currency_code
, created_at
from numerus.quote
where false;
select 1 / count(*) from pg_class where oid = 'numerus.quote'::regclass and relrowsecurity;
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.quote'::regclass;
rollback;

10
verify/quote_contact.sql Normal file
View File

@ -0,0 +1,10 @@
-- Verify numerus:quote_contact on pg
begin;
select quote_id
, contact_id
from numerus.quote_contact
where false;
rollback;

View File

@ -0,0 +1,10 @@
-- Verify numerus:quote_payment_method on pg
begin;
select quote_id
, payment_method_id
from numerus.quote_payment_method
where false;
rollback;

18
verify/quote_product.sql Normal file
View File

@ -0,0 +1,18 @@
-- Verify numerus:quote_product on pg
begin;
select quote_product_id
, quote_id
, name
, description
, price
, quantity
, discount_rate
from numerus.quote_product
where false;
select 1 / count(*) from pg_class where oid = 'numerus.quote_product'::regclass and relrowsecurity;
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.quote_product'::regclass;
rollback;

View File

@ -0,0 +1,10 @@
-- Verify numerus:quote_product_product on pg
begin;
select quote_product_id
, product_id
from numerus.quote_product_product
where false;
rollback;

View File

@ -0,0 +1,14 @@
-- Verify numerus:quote_product_tax on pg
begin;
select quote_product_id
, tax_id
, tax_rate
from numerus.quote_product_tax
where false;
select 1 / count(*) from pg_class where oid = 'numerus.quote_product_tax'::regclass and relrowsecurity;
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.quote_product_tax'::regclass;
rollback;

10
verify/quote_status.sql Normal file
View File

@ -0,0 +1,10 @@
-- Verify numerus:quote_status on pg
begin;
select quote_status
, name
from numerus.quote_status
where false;
rollback;

View File

@ -0,0 +1,11 @@
-- Verify numerus:quote_status_i18n on pg
begin;
select quote_status
, lang_tag
, name
from numerus.quote_status_i18n
where false;
rollback;