numerus/test/add_invoice.sql

152 lines
6.7 KiB
MySQL
Raw Permalink Normal View History

2023-02-16 22:09:10 +00:00
-- Test add_invoice
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(16);
2023-02-16 22:09:10 +00:00
set search_path to auth, numerus, public;
select has_function('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]']);
select function_lang_is('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'plpgsql');
select function_returns('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'uuid');
select isnt_definer('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]']);
select volatility_is('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'volatile');
select function_privs_are('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'guest', array []::text[]);
select function_privs_are('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'add_invoice', array ['integer', 'date', 'integer', 'text', 'integer', 'tag_name[]', 'new_invoice_product[]'], 'authenticator', array []::text[]);
2023-02-16 22:09:10 +00:00
set client_min_messages to warning;
truncate invoice_number_counter cascade;
2023-02-16 22:09:10 +00:00
truncate invoice_product_tax cascade;
truncate invoice_product cascade;
truncate invoice cascade;
Split contact relation into tax_details, phone, web, and email We need to have contacts with just a name: we need to assign freelancer’s quote as expense linked the government, but of course we do not have a phone or email for that “contact”, much less a VATIN or other tax details. It is also interesting for other expenses-only contacts to not have to input all tax details, as we may not need to invoice then, thus are useless for us, but sometimes it might be interesting to have them, “just in case”. Of course, i did not want to make nullable any of the tax details required to generate an invoice, otherwise we could allow illegal invoices. Therefore, that data had to go in a different relation, and invoice’s foreign key update to point to that relation, not just customer, or we would again be able to create invalid invoices. We replaced the contact’s trade name with just name, because we do not need _three_ names for a contact, but we _do_ need two: the one we use to refer to them and the business name for tax purposes. The new contact_phone, contact_web, and contact_email relations could be simply a nullable field, but i did not see the point, since there are not that many instances where i need any of this data. Now company.taxDetailsForm is no longer “the same as contactForm with some extra fields”, because i have to add a check whether the user needs to invoice the contact, to check that the required values are there. I have an additional problem with the contact form when not using JavaScript: i must set the required field to all tax details fields to avoid the “(optional)” suffix, and because they _are_ required when that checkbox is enabled, but i can not set them optional when the check is unchecked. My solution for now is to ignore the form validation, and later i will add some JavaScript that adds the validation again, so it will work in all cases.
2023-06-30 19:32:48 +00:00
truncate contact_tax_details cascade;
2023-02-16 22:09:10 +00:00
truncate contact cascade;
truncate product cascade;
truncate tax cascade;
truncate tax_class cascade;
truncate payment_method cascade;
2023-02-16 22:09:10 +00:00
truncate company cascade;
reset client_min_messages;
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, invoice_number_format, default_payment_method_id)
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', '"F"YYYY0000', 111)
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', '"INV"000-YY', 222)
;
insert into payment_method (payment_method_id, company_id, name, instructions)
values (111, 1, 'cash', 'cash')
, (222, 2, 'cash', 'cash')
;
set constraints "company_default_payment_method_id_fkey" immediate;
insert into invoice_number_counter (company_id, year, currval)
values (1, 2023, '5')
, (2, 2023, '55')
2023-02-16 22:09:10 +00:00
;
insert into tax_class (tax_class_id, company_id, name)
values (11, 1, 'tax')
, (22, 2, 'tax')
;
insert into tax (tax_id, company_id, tax_class_id, name, rate)
values (3, 1, 11, 'IRPF -15 %', -0.15)
, (4, 1, 11, 'IVA 21 %', 0.21)
, (5, 2, 22, 'IRPF -7 %', -0.07)
, (6, 2, 22, 'IVA 10 %', 0.10)
2023-02-16 22:09:10 +00:00
;
insert into product (product_id, company_id, name, price)
values ( 7, 1, 'Product 2.1', 1212)
, ( 8, 1, 'Product 2.2', 2424)
, ( 9, 2, 'Product 4.1', 4848)
, (10, 2, 'Product 4.2', 9696)
, (11, 2, 'Product 4.3', 1010)
2023-02-16 22:09:10 +00:00
;
Split contact relation into tax_details, phone, web, and email We need to have contacts with just a name: we need to assign freelancer’s quote as expense linked the government, but of course we do not have a phone or email for that “contact”, much less a VATIN or other tax details. It is also interesting for other expenses-only contacts to not have to input all tax details, as we may not need to invoice then, thus are useless for us, but sometimes it might be interesting to have them, “just in case”. Of course, i did not want to make nullable any of the tax details required to generate an invoice, otherwise we could allow illegal invoices. Therefore, that data had to go in a different relation, and invoice’s foreign key update to point to that relation, not just customer, or we would again be able to create invalid invoices. We replaced the contact’s trade name with just name, because we do not need _three_ names for a contact, but we _do_ need two: the one we use to refer to them and the business name for tax purposes. The new contact_phone, contact_web, and contact_email relations could be simply a nullable field, but i did not see the point, since there are not that many instances where i need any of this data. Now company.taxDetailsForm is no longer “the same as contactForm with some extra fields”, because i have to add a check whether the user needs to invoice the contact, to check that the required values are there. I have an additional problem with the contact form when not using JavaScript: i must set the required field to all tax details fields to avoid the “(optional)” suffix, and because they _are_ required when that checkbox is enabled, but i can not set them optional when the check is unchecked. My solution for now is to ignore the form validation, and later i will add some JavaScript that adds the validation again, so it will work in all cases.
2023-06-30 19:32:48 +00:00
insert into contact (contact_id, company_id, name)
values (12, 1, 'Contact 2.1')
, (13, 1, 'Contact 2.2')
, (14, 2, 'Contact 4.1')
, (15, 2, 'Contact 4.2')
;
insert into contact_tax_details (contact_id, business_name, vatin, address, city, province, postal_code, country_code)
values (12, 'Contact 2.1', 'XX555', '', '', '', '', 'ES')
, (13, 'Contact 2.2', 'XX666', '', '', '', '', 'ES')
, (14, 'Contact 4.1', 'XX777', '', '', '', '', 'ES')
, (15, 'Contact 4.2', 'XX888', '', '', '', '', 'ES')
2023-02-16 22:09:10 +00:00
;
select lives_ok(
$$ select add_invoice(1, '2023-02-15', 12, 'Notes 1', 111, '{tag1,tag2}','{"(7,Product 1,Description 1,12.24,2,0.0,{4})"}') $$,
2023-02-16 22:09:10 +00:00
'Should be able to insert an invoice for the first company with a product'
);
select lives_ok(
$$ select add_invoice(1, '2023-02-16', 13, 'Notes 2', 111, '{}', '{"(7,Product 1 bis,Description 1 bis,33.33,1,0.50,\"{4,3}\")","(8,Product 2,Description 2,24.00,3,0.75,{})"}') $$,
2023-02-16 22:09:10 +00:00
'Should be able to insert a second invoice for the first company with two product'
);
select lives_ok(
$$ select add_invoice(2, '2023-02-14', 15, 'Notes 3', 222, '{tag3}','{"(11,Product 4.3,,11.11,1,0.0,{6})","(,Product 4.4,Description 4.4,22.22,3,0.05,{})"}') $$,
2023-02-16 22:09:10 +00:00
'Should be able to insert an invoice for the second company with a product'
);
select bag_eq(
$$ select company_id, invoice_number, invoice_date, contact_id, invoice_status, notes, payment_method_id, currency_code, tags, created_at from invoice $$,
$$ values (1, 'F20230006', '2023-02-15'::date, 12, 'created', 'Notes 1', 111, 'EUR', '{tag1,tag2}'::tag_name[], current_timestamp)
, (1, 'F20230007', '2023-02-16'::date, 13, 'created', 'Notes 2', 111, 'EUR', '{}'::tag_name[], current_timestamp)
, (2, 'INV056-23', '2023-02-14'::date, 15, 'created', 'Notes 3', 222, 'USD', '{tag3}'::tag_name[], current_timestamp)
2023-02-16 22:09:10 +00:00
$$,
'Should have created all invoices'
);
select bag_eq(
$$ select invoice_number, name, description, price, quantity, discount_rate from invoice_product join invoice using (invoice_id) $$,
$$ values ('F20230006', 'Product 1', 'Description 1', 1224, 2, 0.00)
, ('F20230007', 'Product 1 bis', 'Description 1 bis', 3333, 1, 0.50)
, ('F20230007', 'Product 2', 'Description 2', 2400, 3, 0.75)
, ('INV056-23', 'Product 4.3', '', 1111, 1, 0.0)
, ('INV056-23', 'Product 4.4', 'Description 4.4', 2222, 3, 0.05)
2023-02-16 22:09:10 +00:00
$$,
'Should have created all invoice products'
);
select bag_eq(
$$ select invoice_number, product_id, name from invoice_product left join invoice_product_product using (invoice_product_id) join invoice using (invoice_id) $$,
$$ values ('F20230006', 7, 'Product 1')
, ('F20230007', 7, 'Product 1 bis')
, ('F20230007', 8, 'Product 2')
, ('INV056-23', 11, 'Product 4.3')
, ('INV056-23', NULL, 'Product 4.4')
$$,
'Should have linked all invoice products'
);
select bag_eq(
$$ select invoice_number, name, tax_id, tax_rate from invoice_product_tax join invoice_product using (invoice_product_id) join invoice using (invoice_id) $$,
$$ values ('F20230006', 'Product 1', 4, 0.21)
, ('F20230007', 'Product 1 bis', 4, 0.21)
, ('F20230007', 'Product 1 bis', 3, -0.15)
, ('INV056-23', 'Product 4.3', 6, 0.10)
2023-02-16 22:09:10 +00:00
$$,
'Should have created all invoice product taxes'
);
select *
from finish();
rollback;