Compare commits

...

2 Commits

Author SHA1 Message Date
jordi fita mas 880c4f53b2 Add the function to get the next invoice number
I can not use a PostgreSQL sequence because invoices need to be gapless,
and sequences are designed to not rollback, for performance reasons.  In
this case, the performance is secondary because the law does not care.
2023-02-17 14:48:24 +01:00
jordi fita mas de7d167e65 Add constraints to reject empty product and companies names 2023-02-17 12:39:32 +01:00
25 changed files with 382 additions and 31 deletions

View File

@ -14,7 +14,7 @@ set search_path to numerus,public;
create table company ( create table company (
company_id serial primary key, company_id serial primary key,
slug uuid not null unique default gen_random_uuid(), slug uuid not null unique default gen_random_uuid(),
business_name text not null, business_name text not null constraint business_name_not_empty check (length(trim(business_name)) > 1),
vatin vatin not null, vatin vatin not null,
trade_name text not null, trade_name text not null,
phone packed_phone_number not null, phone packed_phone_number not null,
@ -26,6 +26,7 @@ create table company (
postal_code text not null, postal_code text not null,
country_code country_code not null references country, country_code country_code not null references country,
currency_code currency_code not null references currency, currency_code currency_code not null references currency,
invoice_number_format text not null default '"FRA"YYYY0000',
created_at timestamptz not null default current_timestamp created_at timestamptz not null default current_timestamp
); );

View File

@ -18,7 +18,7 @@ create table contact (
contact_id serial primary key, contact_id serial primary key,
company_id integer not null references company, company_id integer not null references company,
slug uuid not null unique default gen_random_uuid(), slug uuid not null unique default gen_random_uuid(),
business_name text not null, business_name text not null constraint business_name_not_empty check(length(trim(business_name)) > 1),
vatin vatin not null, vatin vatin not null,
trade_name text not null, trade_name text not null,
phone packed_phone_number not null, phone packed_phone_number not null,

View File

@ -13,7 +13,7 @@ create table invoice (
invoice_id serial primary key, invoice_id serial primary key,
company_id integer not null references company, company_id integer not null references company,
slug uuid not null unique default gen_random_uuid(), slug uuid not null unique default gen_random_uuid(),
invoice_number text not null, invoice_number text not null constraint invoice_number_not_empty check(length(trim(invoice_number)) > 1),
invoice_date date not null default current_date, invoice_date date not null default current_date,
contact_id integer not null references contact, contact_id integer not null references contact,
invoice_status text not null default 'created' references invoice_status, invoice_status text not null default 'created' references invoice_status,

View File

@ -0,0 +1,32 @@
-- Deploy numerus:invoice_number_counter to pg
-- requires: schema_numerus
-- requires: company
begin;
set search_path to numerus, public;
create table invoice_number_counter (
company_id integer not null,
year integer not null constraint year_always_positive check(year > 0),
currval integer not null constraint counter_always_positive check(currval > 0),
primary key (company_id, year)
);
grant select, insert, update on table invoice_number_counter to invoicer;
grant select, insert, update on table invoice_number_counter to admin;
alter table invoice_number_counter enable row level security;
create policy company_policy
on invoice_number_counter
using (
exists(
select 1
from company_user
join user_profile using (user_id)
where company_user.company_id = invoice_number_counter.company_id
)
);
commit;

View File

@ -11,10 +11,10 @@ create table invoice_product (
invoice_product_id serial primary key, invoice_product_id serial primary key,
invoice_id integer not null references invoice, invoice_id integer not null references invoice,
product_id integer not null references product, product_id integer not null references product,
name text not null, name text not null constraint name_not_empty check(length(trim(name)) > 0),
description text not null, description text not null default '',
price integer not null, price integer not null,
quantity integer not null, quantity integer not null default 1,
discount_rate discount_rate not null default 0.0 discount_rate discount_rate not null default 0.0
); );

View File

@ -0,0 +1,38 @@
-- Deploy numerus:next_invoice_number to pg
-- requires: schema_numerus
-- requires: invoice_number_counter
begin;
set search_path to numerus, public;
create or replace function next_invoice_number(company integer, invoice_date date) returns text
as
$$
declare
num integer;
invoice_number text;
begin
insert into invoice_number_counter (company_id, year, currval)
values (next_invoice_number.company, date_part('year', invoice_date), 1)
on conflict (company_id, year) do
update
set currval = invoice_number_counter.currval + 1
returning currval
into num;
select to_char(invoice_date, to_char(num, 'FM' || replace(invoice_number_format, '"', '\""')))
into invoice_number
from company
where company_id = next_invoice_number.company;
return invoice_number;
end;
$$
language plpgsql;
revoke execute on function next_invoice_number(integer, date) from public;
grant execute on function next_invoice_number(integer, date) to invoicer;
grant execute on function next_invoice_number(integer, date) to admin;
commit;

View File

@ -11,8 +11,8 @@ create table product (
product_id serial primary key, product_id serial primary key,
company_id integer not null references company, company_id integer not null references company,
slug uuid not null default gen_random_uuid(), slug uuid not null default gen_random_uuid(),
name text not null, name text not null constraint name_not_empty check(length(trim(name)) > 0),
description text not null, description text not null default '',
price integer not null, price integer not null,
created_at timestamptz not null default current_timestamp created_at timestamptz not null default current_timestamp
); );

View File

@ -10,7 +10,7 @@ set search_path to numerus, public;
create table tax ( create table tax (
tax_id serial primary key, tax_id serial primary key,
company_id integer not null references company, company_id integer not null references company,
name text not null, name text not null constraint name_not_empty check(length(trim(name)) > 0),
rate tax_rate not null rate tax_rate not null
); );

View File

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

View File

@ -1,6 +1,6 @@
-- Revert numerus:new_invoice_product from pg -- Revert numerus:new_invoice_product from pg
begin begin;
drop type if exists numerus.new_invoice_product; drop type if exists numerus.new_invoice_product;

View File

@ -0,0 +1,7 @@
-- Revert numerus:next_invoice_number from pg
begin;
drop function if exists numerus.next_invoice_number(integer, date);
commit;

View File

@ -54,3 +54,5 @@ edit_product [schema_numerus product product_tax parse_price company currency] 2
invoice_product_tax [schema_numerus invoice_product tax tax_rate] 2023-02-15T13:20:30Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes in invoice products invoice_product_tax [schema_numerus invoice_product tax tax_rate] 2023-02-15T13:20:30Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes in invoice products
new_invoice_product [schema_numerus] 2023-02-16T21:06:01Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to new invoices new_invoice_product [schema_numerus] 2023-02-16T21:06:01Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to new invoices
add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices add_invoice [schema_numerus invoice company currency parse_price new_invoice_product tax invoice_product invoice_product_tax] 2023-02-16T21:12:46Z jordi fita mas <jordi@tandem.blog> # Add function to create new invoices
invoice_number_counter [schema_numerus company] 2023-02-17T13:04:48Z jordi fita mas <jordi@tandem.blog> # Add relation to count invoice numbers
next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z jordi fita mas <jordi@tandem.blog> # Add function to retrieve the next invoice number

View File

@ -42,12 +42,12 @@ values (3, 1, 'IRPF -15 %', -0.15)
, (6, 2, 'IVA 10 %', 0.10) , (6, 2, 'IVA 10 %', 0.10)
; ;
insert into product (product_id, company_id, name, description, price) insert into product (product_id, company_id, name, price)
values ( 7, 1, 'Product 2.1', '', 1212) values ( 7, 1, 'Product 2.1', 1212)
, ( 8, 1, 'Product 2.2', '', 2424) , ( 8, 1, 'Product 2.2', 2424)
, ( 9, 2, 'Product 4.1', '', 4848) , ( 9, 2, 'Product 4.1', 4848)
, (10, 2, 'Product 4.2', '', 9696) , (10, 2, 'Product 4.2', 9696)
, (11, 2, 'Product 4.3', '', 1010) , (11, 2, 'Product 4.3', 1010)
; ;
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code) insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(79); select plan(85);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -94,6 +94,12 @@ select col_type_is('company', 'currency_code', 'currency_code');
select col_not_null('company', 'currency_code'); select col_not_null('company', 'currency_code');
select col_hasnt_default('company', 'currency_code'); select col_hasnt_default('company', 'currency_code');
select has_column('company', 'invoice_number_format');
select col_type_is('company', 'invoice_number_format', 'text');
select col_not_null('company', 'invoice_number_format');
select col_has_default('company', 'invoice_number_format');
select col_default_is('company', 'invoice_number_format', '"FRA"YYYY0000');
select has_column('company', 'created_at'); select has_column('company', 'created_at');
select col_type_is('company', 'created_at', 'timestamp with time zone'); select col_type_is('company', 'created_at', 'timestamp with time zone');
select col_not_null('company', 'created_at'); select col_not_null('company', 'created_at');
@ -162,5 +168,13 @@ select throws_ok(
); );
reset role; reset role;
select throws_ok( $$
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code)
values (7, ' ', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR')
$$,
'23514', 'new row for relation "company" violates check constraint "business_name_not_empty"',
'Should not allow companies with blank business name'
);
select finish(); select finish();
rollback; rollback;

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(84); select plan(85);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -168,6 +168,15 @@ select throws_ok(
); );
reset role; reset role;
select throws_ok( $$
insert into contact (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
values (2, ' ', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES')
$$,
'23514', 'new row for relation "contact" violates check constraint "business_name_not_empty"',
'Should not allow contacts with blank business name'
);
select * select *
from finish(); from finish();

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(71); select plan(72);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -159,6 +159,15 @@ select throws_ok(
reset role; reset role;
select throws_ok( $$
insert into invoice (company_id, invoice_number, contact_id, currency_code)
values (2, ' ', 6, 'EUR')
$$,
'23514', 'new row for relation "invoice" violates check constraint "invoice_number_not_empty"',
'Should not allow invoice with blank number'
);
select * select *
from finish(); from finish();

View File

@ -0,0 +1,131 @@
-- Test invoice_number_counter
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(25);
set search_path to numerus, auth, public;
select has_table('invoice_number_counter');
select has_pk('invoice_number_counter' );
select col_is_pk('invoice_number_counter', array['company_id', 'year']);
select table_privs_are('invoice_number_counter', 'guest', array []::text[]);
select table_privs_are('invoice_number_counter', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE']);
select table_privs_are('invoice_number_counter', 'admin', array ['SELECT', 'INSERT', 'UPDATE']);
select table_privs_are('invoice_number_counter', 'authenticator', array []::text[]);
select has_column('invoice_number_counter', 'company_id');
select col_type_is('invoice_number_counter', 'company_id', 'integer');
select col_not_null('invoice_number_counter', 'company_id');
select col_hasnt_default('invoice_number_counter', 'company_id');
select has_column('invoice_number_counter', 'year');
select col_type_is('invoice_number_counter', 'year', 'integer');
select col_not_null('invoice_number_counter', 'year');
select col_hasnt_default('invoice_number_counter', 'year');
select has_column('invoice_number_counter', 'currval');
select col_type_is('invoice_number_counter', 'currval', 'integer');
select col_not_null('invoice_number_counter', 'currval');
select col_hasnt_default('invoice_number_counter', 'currval');
set client_min_messages to warning;
truncate invoice_number_counter 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_number_counter (company_id, year, currval)
values (2, 2010, 6)
, (2, 2011, 8)
, (4, 2010, 8)
, (4, 2012, 10)
;
prepare counter_data as
select company_id, year, currval
from invoice_number_counter
;
set role invoicer;
select is_empty('counter_data', 'Should show no data when cookie is not set yet');
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select bag_eq(
'counter_data',
$$ values (2, 2010, 6)
, (2, 2011, 8)
$$,
'Should only list invoices of the companies where demo@tandem.blog is user of'
);
reset role;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
select bag_eq(
'counter_data',
$$ values (4, 2010, 8)
, (4, 2012, 10)
$$,
'Should only list invoices of the companies where admin@tandem.blog is user of'
);
reset role;
select set_cookie('not-a-cookie');
select throws_ok(
'counter_data',
'42501', 'permission denied for table invoice_number_counter',
'Should not allow select to guest users'
);
reset role;
select throws_ok( $$
insert into invoice_number_counter (company_id, year, currval)
values (2, 2008, 0)
$$,
'23514', 'new row for relation "invoice_number_counter" violates check constraint "counter_always_positive"',
'Should not allow starting a counter from zero'
);
select throws_ok( $$
insert into invoice_number_counter (company_id, year, currval)
values (2, -2008, 1)
$$,
'23514', 'new row for relation "invoice_number_counter" violates check constraint "year_always_positive"',
'Should not allow counters for invoices issued before Jesus Christ was born'
);
select *
from finish();
rollback;

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(54); select plan(57);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -51,7 +51,8 @@ select col_hasnt_default('invoice_product', 'name');
select has_column('invoice_product', 'description'); select has_column('invoice_product', 'description');
select col_type_is('invoice_product', 'description', 'text'); select col_type_is('invoice_product', 'description', 'text');
select col_not_null('invoice_product', 'description'); select col_not_null('invoice_product', 'description');
select col_hasnt_default('invoice_product', 'description'); select col_has_default('invoice_product', 'description');
select col_default_is('invoice_product', 'description', '');
select has_column('invoice_product', 'price'); select has_column('invoice_product', 'price');
select col_type_is('invoice_product', 'price', 'integer'); select col_type_is('invoice_product', 'price', 'integer');
@ -61,7 +62,8 @@ select col_hasnt_default('invoice_product', 'price');
select has_column('invoice_product', 'quantity'); select has_column('invoice_product', 'quantity');
select col_type_is('invoice_product', 'quantity', 'integer'); select col_type_is('invoice_product', 'quantity', 'integer');
select col_not_null('invoice_product', 'quantity'); select col_not_null('invoice_product', 'quantity');
select col_hasnt_default('invoice_product', 'quantity'); select col_has_default('invoice_product', 'quantity');
select col_default_is('invoice_product', 'quantity', 1);
select has_column('invoice_product', 'discount_rate'); select has_column('invoice_product', 'discount_rate');
select col_type_is('invoice_product', 'discount_rate', 'discount_rate'); select col_type_is('invoice_product', 'discount_rate', 'discount_rate');
@ -151,6 +153,16 @@ select throws_ok(
); );
reset role; reset role;
select throws_ok( $$
insert into invoice_product (invoice_id, product_id, name, description, price, quantity)
values (10, 14, ' ', '', 1212, 1)
$$,
'23514', 'new row for relation "invoice_product" violates check constraint "name_not_empty"',
'Should not allow invoice products with blank name'
);
select * select *
from finish(); from finish();

View File

@ -69,9 +69,9 @@ values (3, 2, 'IVA 21 %', 0.21)
, (6, 4, 'IVA 10 %', 0.10) , (6, 4, 'IVA 10 %', 0.10)
; ;
insert into product (product_id, company_id, name, description, price) insert into product (product_id, company_id, name, price)
values (7, 2, 'Product 1', 'Description 1', 1200) values (7, 2, 'Product 1', 1200)
, (8, 4, 'Product 2', 'Description 2', 2400) , (8, 4, 'Product 2', 2400)
; ;
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code) insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
@ -84,9 +84,9 @@ values (11, 2, 'INV001', 9, 'EUR')
, (12, 4, 'INV002', 10, 'EUR') , (12, 4, 'INV002', 10, 'EUR')
; ;
insert into invoice_product (invoice_product_id, invoice_id, product_id, name, description, price, quantity) insert into invoice_product (invoice_product_id, invoice_id, product_id, name, price)
values (13, 11, 7, 'Product 1', '', 1200, 1) values (13, 11, 7, 'Product 1', 1200)
, (14, 12, 8, 'Product 2', '', 2400, 2) , (14, 12, 8, 'Product 2', 2400)
; ;
insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate) insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate)

View File

@ -0,0 +1,50 @@
-- Test next_invoice_number
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(17);
set search_path to numerus, public;
select has_function('numerus', 'next_invoice_number', array ['integer', 'date']);
select function_lang_is('numerus', 'next_invoice_number', array ['integer', 'date'], 'plpgsql');
select function_returns('numerus', 'next_invoice_number', array ['integer', 'date'], 'text');
select isnt_definer('numerus', 'next_invoice_number', array ['integer', 'date']);
select volatility_is('numerus', 'next_invoice_number', array ['integer', 'date'], 'volatile');
select function_privs_are('numerus', 'next_invoice_number', array ['integer', 'date'], 'guest', array []::text[]);
select function_privs_are('numerus', 'next_invoice_number', array ['integer', 'date'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'next_invoice_number', array ['integer', 'date'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'next_invoice_number', array ['integer', 'date'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate invoice_number_counter cascade;
truncate company cascade;
reset client_min_messages;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, invoice_number_format)
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', '"F"YYYY0000')
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', '"INV"000-YY')
;
insert into invoice_number_counter (company_id, year, currval)
values (1, 2010, 5)
, (2, 2010, 6)
;
select is( next_invoice_number(1, '2010-12-25'), 'F20100006' );
select is( next_invoice_number(2, '2010-12-25'), 'INV007-10' );
select is( next_invoice_number(1, '2010-10-17'), 'F20100007' );
select is( next_invoice_number(2, '2010-10-17'), 'INV008-10' );
select is( next_invoice_number(1, '2011-12-25'), 'F20110001' );
select is( next_invoice_number(2, '2012-12-25'), 'INV001-12' );
select is( next_invoice_number(1, '2011-12-25'), 'F20110002' );
select is( next_invoice_number(2, '2012-12-25'), 'INV002-12' );
select *
from finish();
rollback;

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(49); select plan(51);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -50,7 +50,8 @@ select col_hasnt_default('product', 'name');
select has_column('product', 'description'); select has_column('product', 'description');
select col_type_is('product', 'description', 'text'); select col_type_is('product', 'description', 'text');
select col_not_null('product', 'description'); select col_not_null('product', 'description');
select col_hasnt_default('product', 'description'); select col_has_default('product', 'description');
select col_default_is('product', 'description', '');
select has_column('product', 'price'); select has_column('product', 'price');
select col_type_is('product', 'price', 'integer'); select col_type_is('product', 'price', 'integer');
@ -127,6 +128,15 @@ select throws_ok(
reset role; reset role;
select throws_ok( $$
insert into product (company_id, name, description, price)
values (2, ' ', '', 1200)
$$,
'23514', 'new row for relation "product" violates check constraint "name_not_empty"',
'Should not allow product with blank name'
);
select * select *
from finish(); from finish();

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin; begin;
select plan(35); select plan(36);
set search_path to numerus, auth, public; set search_path to numerus, auth, public;
@ -119,6 +119,13 @@ select throws_ok(
); );
reset role; reset role;
select throws_ok( $$
insert into tax (company_id, name, rate)
values (2, ' ', 0.22)
$$,
'23514', 'new row for relation "tax" violates check constraint "name_not_empty"',
'Should not allow taxs with blank name'
);
select * select *
from finish(); from finish();

View File

@ -16,6 +16,7 @@ select company_id
, postal_code , postal_code
, country_code , country_code
, currency_code , currency_code
, invoice_number_format
, created_at , created_at
from numerus.company from numerus.company
where false; where false;

View File

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

View File

@ -0,0 +1,7 @@
-- Verify numerus:next_invoice_number on pg
begin;
select has_function_privilege('numerus.next_invoice_number(integer, date)', 'execute');
rollback;