diff --git a/deploy/company.sql b/deploy/company.sql index d07096f..ee5ea2f 100644 --- a/deploy/company.sql +++ b/deploy/company.sql @@ -26,6 +26,7 @@ create table company ( postal_code text not null, country_code country_code not null references country, 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 ); diff --git a/deploy/invoice_number_counter.sql b/deploy/invoice_number_counter.sql new file mode 100644 index 0000000..255b8f3 --- /dev/null +++ b/deploy/invoice_number_counter.sql @@ -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; diff --git a/deploy/next_invoice_number.sql b/deploy/next_invoice_number.sql new file mode 100644 index 0000000..88cd46e --- /dev/null +++ b/deploy/next_invoice_number.sql @@ -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; diff --git a/revert/invoice_number_counter.sql b/revert/invoice_number_counter.sql new file mode 100644 index 0000000..8c18391 --- /dev/null +++ b/revert/invoice_number_counter.sql @@ -0,0 +1,7 @@ +-- Revert numerus:invoice_number_counter from pg + +begin; + +drop table if exists numerus.invoice_number_counter; + +commit; diff --git a/revert/next_invoice_number.sql b/revert/next_invoice_number.sql new file mode 100644 index 0000000..d7811bc --- /dev/null +++ b/revert/next_invoice_number.sql @@ -0,0 +1,7 @@ +-- Revert numerus:next_invoice_number from pg + +begin; + +drop function if exists numerus.next_invoice_number(integer, date); + +commit; diff --git a/sqitch.plan b/sqitch.plan index 269ca73..001bbd5 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -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 # Add relation for taxes in invoice products new_invoice_product [schema_numerus] 2023-02-16T21:06:01Z jordi fita mas # 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 # Add function to create new invoices +invoice_number_counter [schema_numerus company] 2023-02-17T13:04:48Z jordi fita mas # Add relation to count invoice numbers +next_invoice_number [schema_numerus invoice_number_counter] 2023-02-17T13:21:48Z jordi fita mas # Add function to retrieve the next invoice number diff --git a/test/company.sql b/test/company.sql index fa0cff5..f53bbe4 100644 --- a/test/company.sql +++ b/test/company.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(80); +select plan(85); 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_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 col_type_is('company', 'created_at', 'timestamp with time zone'); select col_not_null('company', 'created_at'); diff --git a/test/invoice_number_counter.sql b/test/invoice_number_counter.sql new file mode 100644 index 0000000..4601984 --- /dev/null +++ b/test/invoice_number_counter.sql @@ -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; + diff --git a/test/next_invoice_number.sql b/test/next_invoice_number.sql new file mode 100644 index 0000000..c23443a --- /dev/null +++ b/test/next_invoice_number.sql @@ -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; diff --git a/verify/company.sql b/verify/company.sql index c9793a5..bd21fd7 100644 --- a/verify/company.sql +++ b/verify/company.sql @@ -16,6 +16,7 @@ select company_id , postal_code , country_code , currency_code + , invoice_number_format , created_at from numerus.company where false; diff --git a/verify/invoice_number_counter.sql b/verify/invoice_number_counter.sql new file mode 100644 index 0000000..db453f7 --- /dev/null +++ b/verify/invoice_number_counter.sql @@ -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; diff --git a/verify/next_invoice_number.sql b/verify/next_invoice_number.sql new file mode 100644 index 0000000..966bd0a --- /dev/null +++ b/verify/next_invoice_number.sql @@ -0,0 +1,7 @@ +-- Verify numerus:next_invoice_number on pg + +begin; + +select has_function_privilege('numerus.next_invoice_number(integer, date)', 'execute'); + +rollback;