diff --git a/deploy/add_invoice.sql b/deploy/add_invoice.sql new file mode 100644 index 0000000..7c998c9 --- /dev/null +++ b/deploy/add_invoice.sql @@ -0,0 +1,67 @@ +-- Deploy numerus:add_invoice to pg +-- requires: schema_numerus +-- requires: invoice +-- requires: company +-- requires: currency +-- requires: parse_price +-- requires: new_invoice_product +-- requires: tax +-- requires: invoice_product +-- requires: invoice_product_tax + +begin; + +set search_path to numerus, public; + +create or replace function add_invoice(company_id integer, invoice_number text, invoice_date date, contact_id integer, notes text, products new_invoice_product[]) returns uuid as +$$ +declare + iid integer; + pslug uuid; + product new_invoice_product; + ccode text; + ipid integer; +begin + insert into invoice (company_id, invoice_number, invoice_date, contact_id, notes, currency_code) + select company.company_id + , invoice_number + , invoice_date + , contact_id + , notes + , currency_code + from company + where company.company_id = add_invoice.company_id + returning invoice_id, slug, currency_code + into iid, pslug, ccode; + + foreach product in array products + loop + insert into invoice_product (invoice_id, product_id, name, description, price, quantity, discount_rate) + select iid + , product.product_id + , product.name + , coalesce(product.description, '') + , parse_price(product.price, currency.decimal_digits) + , product.quantity + , product.discount_rate + from currency + where currency_code = ccode + returning invoice_product_id + into ipid; + + insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate) + select ipid, tax_id, tax.rate + from tax + join unnest(product.tax) as ptax(tax_id) using (tax_id); + end loop; + + return pslug; +end; +$$ +language plpgsql; + +revoke execute on function add_invoice(integer, text, date, integer, text, new_invoice_product[]) from public; +grant execute on function add_invoice(integer, text, date, integer, text, new_invoice_product[]) to invoicer; +grant execute on function add_invoice(integer, text, date, integer, text, new_invoice_product[]) to admin; + +commit; diff --git a/deploy/new_invoice_product.sql b/deploy/new_invoice_product.sql new file mode 100644 index 0000000..d036259 --- /dev/null +++ b/deploy/new_invoice_product.sql @@ -0,0 +1,18 @@ +-- Deploy numerus:new_invoice_product to pg +-- requires: schema_numerus + +begin; + +set search_path to numerus, public; + +create type new_invoice_product as ( + product_id integer, + name text, + description text, + price text, + quantity integer, + discount_rate discount_rate, + tax integer[] +); + +commit; diff --git a/revert/add_invoice.sql b/revert/add_invoice.sql new file mode 100644 index 0000000..414abb9 --- /dev/null +++ b/revert/add_invoice.sql @@ -0,0 +1,7 @@ +-- Revert numerus:add_invoice from pg + +begin; + +drop function if exists numerus.add_invoice(integer, text, date, integer, text, numerus.new_invoice_product[]); + +commit; diff --git a/revert/new_invoice_product.sql b/revert/new_invoice_product.sql new file mode 100644 index 0000000..88c39be --- /dev/null +++ b/revert/new_invoice_product.sql @@ -0,0 +1,7 @@ +-- Revert numerus:new_invoice_product from pg + +begin + +drop type if exists numerus.new_invoice_product; + +commit; diff --git a/sqitch.plan b/sqitch.plan index 49e953d..269ca73 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -52,3 +52,5 @@ invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jord add_product [schema_numerus product product_tax parse_price company currency] 2023-02-14T10:32:18Z jordi fita mas # Add function to add new products edit_product [schema_numerus product product_tax parse_price company currency] 2023-02-14T11:06:03Z jordi fita mas # Add function to edit products 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 diff --git a/test/add_invoice.sql b/test/add_invoice.sql new file mode 100644 index 0000000..553a1c6 --- /dev/null +++ b/test/add_invoice.sql @@ -0,0 +1,109 @@ +-- Test add_invoice +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(15); + +set search_path to auth, numerus, public; + +select has_function('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]']); +select function_lang_is('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'plpgsql'); +select function_returns('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'uuid'); +select isnt_definer('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]']); +select volatility_is('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'volatile'); +select function_privs_are('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'guest', array []::text[]); +select function_privs_are('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'invoicer', array ['EXECUTE']); +select function_privs_are('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'admin', array ['EXECUTE']); +select function_privs_are('numerus', 'add_invoice', array ['integer', 'text', 'date', 'integer', 'text', 'new_invoice_product[]'], 'authenticator', array []::text[]); + + +set client_min_messages to warning; +truncate invoice_product_tax cascade; +truncate invoice_product cascade; +truncate invoice cascade; +truncate contact cascade; +truncate product cascade; +truncate tax 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) +values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR') + , (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD') +; + +insert into tax (tax_id, company_id, name, rate) +values (3, 1, 'IRPF -15 %', -0.15) + , (4, 1, 'IVA 21 %', 0.21) + , (5, 2, 'IRPF -7 %', -0.07) + , (6, 2, 'IVA 10 %', 0.10) +; + +insert into product (product_id, company_id, name, description, 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) +; + +insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code) +values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES') + , (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES') + , (14, 2, 'Contact 4.1', 'XX777', '', '999-999-999', 'e@e', '', '', '', '', '', 'ES') + , (15, 2, 'Contact 4.2', 'XX888', '', '000-000-000', 'f@f', '', '', '', '', '', 'ES') +; + + +select lives_ok( + $$ select add_invoice(1, 'INV001', '2023-02-15', 12, 'Notes 1', '{"(7,Product 1,Description 1,12.24,2,0.0,{4})"}') $$, + 'Should be able to insert an invoice for the first company with a product' +); + +select lives_ok( + $$ select add_invoice(1, 'INV002', '2023-02-16', 13, 'Notes 2', '{"(7,Product 1 bis,Description 1 bis,33.33,1,0.50,\"{4,3}\")","(8,Product 2,Description 2,24.00,3,0.75,{})"}') $$, + 'Should be able to insert a second invoice for the first company with two product' +); + +select lives_ok( + $$ select add_invoice(2, 'INV101', '2023-02-14', 15, 'Notes 3', '{"(11,Product 4.3,,11.11,1,0.0,{6})"}') $$, + '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, currency_code, created_at from invoice $$, + $$ values (1, 'INV001', '2023-02-15'::date, 12, 'created', 'Notes 1', 'EUR', current_timestamp) + , (1, 'INV002', '2023-02-16'::date, 13, 'created', 'Notes 2', 'EUR', current_timestamp) + , (2, 'INV101', '2023-02-14'::date, 15, 'created', 'Notes 3', 'USD', current_timestamp) + $$, + 'Should have created all invoices' +); + +select bag_eq( + $$ select invoice_number, product_id, name, description, price, quantity, discount_rate from invoice_product join invoice using (invoice_id) $$, + $$ values ('INV001', 7, 'Product 1', 'Description 1', 1224, 2, 0.00) + , ('INV002', 7, 'Product 1 bis', 'Description 1 bis', 3333, 1, 0.50) + , ('INV002', 8, 'Product 2', 'Description 2', 2400, 3, 0.75) + , ('INV101', 11, 'Product 4.3', '', 1111, 1, 0.0) + $$, + 'Should have created all invoice products' +); + +select bag_eq( + $$ select invoice_number, product_id, tax_id, tax_rate from invoice_product_tax join invoice_product using (invoice_product_id) join invoice using (invoice_id) $$, + $$ values ('INV001', 7, 4, 0.21) + , ('INV002', 7, 4, 0.21) + , ('INV002', 7, 3, -0.15) + , ('INV101', 11, 6, 0.10) + $$, + 'Should have created all invoice product taxes' +); + + +select * +from finish(); + +rollback; diff --git a/test/new_invoice_product.sql b/test/new_invoice_product.sql new file mode 100644 index 0000000..5f88e70 --- /dev/null +++ b/test/new_invoice_product.sql @@ -0,0 +1,26 @@ +-- Test new_invoice_product +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(9); + +set search_path to numerus, public; + +select has_composite('numerus', 'new_invoice_product', 'Composite type numerus.new_invoice_product should exist'); +select columns_are('numerus', 'new_invoice_product', array['product_id', 'name', 'description', 'price', 'quantity', 'discount_rate', 'tax']); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'product_id'::name, 'integer'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'name'::name, 'text'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'description'::name, 'text'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'price'::name, 'text'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'quantity'::name, 'integer'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'discount_rate'::name, 'discount_rate'); +select col_type_is('numerus'::name, 'new_invoice_product'::name, 'tax'::name, 'integer[]'); + + +select * +from finish(); + +rollback; diff --git a/verify/add_invoice.sql b/verify/add_invoice.sql new file mode 100644 index 0000000..e632a8b --- /dev/null +++ b/verify/add_invoice.sql @@ -0,0 +1,7 @@ +-- Verify numerus:add_invoice on pg + +begin; + +select has_function_privilege('numerus.add_invoice(integer, text, date, integer, text, numerus.new_invoice_product[])', 'execute'); + +rollback; diff --git a/verify/new_invoice_product.sql b/verify/new_invoice_product.sql new file mode 100644 index 0000000..089121d --- /dev/null +++ b/verify/new_invoice_product.sql @@ -0,0 +1,7 @@ +-- Verify numerus:new_invoice_product on pg + +begin; + +select pg_catalog.has_type_privilege('numerus.new_invoice_product', 'usage'); + +rollback;