diff --git a/deploy/compute_new_quote_amount.sql b/deploy/compute_new_quote_amount.sql new file mode 100644 index 0000000..a8a8e3e --- /dev/null +++ b/deploy/compute_new_quote_amount.sql @@ -0,0 +1,64 @@ +-- Deploy numerus:compute_new_quote_amount to pg +-- requires: roles +-- requires: schema_numerus +-- requires: company +-- requires: tax +-- requires: new_quote_product +-- requires: new_quote_amount + +begin; + +set search_path to numerus, public; + +create or replace function compute_new_quote_amount(company_id integer, products new_quote_product[]) returns new_quote_amount as +$$ +declare + result new_quote_amount; +begin + if array_length(products, 1) is null then + select to_price(0, decimal_digits), array[]::text[][], to_price(0, decimal_digits) + from company + join currency using (currency_code) + where company.company_id = compute_new_quote_amount.company_id + into result.subtotal, result.taxes, result.total; + else + with product as ( + select round(parse_price(price, currency.decimal_digits) * quantity * (1 - discount_rate))::integer as subtotal + , tax + , decimal_digits + from unnest(products) + join company on company.company_id = compute_new_quote_amount.company_id + join currency using (currency_code) + ) + , tax_amount as ( + select tax_id + , sum(round(subtotal * tax.rate)::integer)::integer as amount + , decimal_digits + from product, unnest(product.tax) as product_tax(tax_id) + join tax using (tax_id) + group by tax_id, decimal_digits + ) + , tax_total as ( + select sum(amount)::integer as amount, array_agg(array[name, to_price(amount, decimal_digits)]) as taxes + from tax_amount + join tax using (tax_id) + ) + select to_price(sum(subtotal)::integer, decimal_digits) + , coalesce(taxes, array[]::text[][]) + , to_price(sum(subtotal)::integer + coalesce(tax_total.amount, 0), decimal_digits) as total + from product, tax_total + group by tax_total.amount, taxes, decimal_digits + into result.subtotal, result.taxes, result.total; + end if; + + return result; +end +$$ +language plpgsql +stable; + +revoke execute on function compute_new_quote_amount(integer, new_quote_product[]) from public; +grant execute on function compute_new_quote_amount(integer, new_quote_product[]) to invoicer; +grant execute on function compute_new_quote_amount(integer, new_quote_product[]) to admin; + +commit; diff --git a/deploy/edit_quote.sql b/deploy/edit_quote.sql new file mode 100644 index 0000000..cc3fdb2 --- /dev/null +++ b/deploy/edit_quote.sql @@ -0,0 +1,132 @@ +-- Deploy numerus:edit_quote to pg +-- requires: roles +-- requires: schema_numerus +-- requires: quote +-- requires: currency +-- requires: parse_price +-- requires: edited_quote_product +-- requires: tax +-- requires: quote_contact +-- requires: quote_payment_method +-- requires: quote_product +-- requires: quote_product_tax +-- requires: quote_product_product +-- requires: tag_name + +begin; + +set search_path to numerus, public; + +create or replace function edit_quote(quote_slug uuid, quote_status text, contact_id integer, terms_and_conditions text, notes text, payment_method_id integer, tags tag_name[], products edited_quote_product[]) returns uuid as +$$ +declare + qid integer; + products_to_keep integer[]; + products_to_delete integer[]; + company integer; + ccode text; + product edited_quote_product; + qpid integer; +begin + update quote + set quote_status = edit_quote.quote_status + , terms_and_conditions = edit_quote.terms_and_conditions + , notes = edit_quote.notes + -- contact_id = edit_quote.contact_id + --, payment_method_id = edit_quote.payment_method_id + , tags = edit_quote.tags + where slug = quote_slug + returning quote_id, company_id, currency_code + into qid, company, ccode + ; + + if qid is null then + return null; + end if; + + if payment_method_id is null then + delete from quote_payment_method where quote_id = qid; + else + insert into quote_payment_method (quote_id, payment_method_id) + values (qid, payment_method_id) + on conflict (quote_id) do update + set payment_method_id = edit_quote.payment_method_id; + end if; + + if contact_id is null then + delete from quote_contact where quote_id = qid; + else + insert into quote_contact (quote_id, contact_id) + values (qid, contact_id) + on conflict (quote_id) do update + set contact_id = edit_quote.contact_id; + end if; + + foreach product in array products + loop + if product.quote_product_id is null then + insert into quote_product (quote_id, name, description, price, quantity, discount_rate) + select qid + , product.name + , coalesce(product.description, '') + , parse_price(product.price, currency.decimal_digits) + , product.quantity + , product.discount_rate + from currency + where currency_code = ccode + returning quote_product_id + into qpid; + else + qpid := product.quote_product_id; + + update quote_product + set name = product.name + , description = coalesce(product.description, '') + , price = parse_price(product.price, currency.decimal_digits) + , quantity = product.quantity + , discount_rate = product.discount_rate + from currency + where quote_product_id = qpid + and currency_code = ccode; + end if; + products_to_keep := array_append(products_to_keep, qpid); + + if product.product_id is null then + delete from quote_product_product where quote_product_id = qpid; + else + insert into quote_product_product (quote_product_id, product_id) + values (qpid, product.product_id) + on conflict (quote_product_id) do update + set product_id = product.product_id; + end if; + + delete from quote_product_tax where quote_product_id = qpid; + + insert into quote_product_tax (quote_product_id, tax_id, tax_rate) + select qpid, tax_id, tax.rate + from tax + join unnest(product.tax) as ptax(tax_id) using (tax_id); + end loop; + + select array_agg(quote_product_id) + into products_to_delete + from quote_product + where quote_id = qid + and not (quote_product_id = any(products_to_keep)); + + if array_length(products_to_delete, 1) > 0 then + delete from quote_product_tax where quote_product_id = any(products_to_delete); + delete from quote_product_product where quote_product_id = any(products_to_delete); + delete from quote_product where quote_product_id = any(products_to_delete); + end if; + + return quote_slug; +end; +$$ +language plpgsql; + +revoke execute on function edit_quote(uuid, text, integer, text, text, integer, tag_name[], edited_quote_product[]) from public; +grant execute on function edit_quote(uuid, text, integer, text, text, integer, tag_name[], edited_quote_product[]) to invoicer; +grant execute on function edit_quote(uuid, text, integer, text, text, integer, tag_name[], edited_quote_product[]) to admin; + +commit; diff --git a/deploy/edited_quote_product.sql b/deploy/edited_quote_product.sql new file mode 100644 index 0000000..7d4e4d1 --- /dev/null +++ b/deploy/edited_quote_product.sql @@ -0,0 +1,20 @@ +-- Deploy numerus:edited_quote_product to pg +-- requires: schema_numerus +-- requires: discount_rate + +begin; + +set search_path to numerus, public; + +create type edited_quote_product as +( quote_product_id integer +, product_id integer +, name text +, description text +, price text +, quantity integer +, discount_rate discount_rate +, tax integer[] +); + +commit; diff --git a/deploy/new_quote_amount.sql b/deploy/new_quote_amount.sql new file mode 100644 index 0000000..93d28c2 --- /dev/null +++ b/deploy/new_quote_amount.sql @@ -0,0 +1,14 @@ +-- Deploy numerus:new_quote_amount to pg +-- requires: schema_numerus + +begin; + +set search_path to numerus, public; + +create type new_quote_amount as ( + subtotal text, + taxes text[][], + total text +); + +commit; diff --git a/deploy/quote_amount.sql b/deploy/quote_amount.sql new file mode 100644 index 0000000..6cb9fb5 --- /dev/null +++ b/deploy/quote_amount.sql @@ -0,0 +1,23 @@ +-- Deploy numerus:quote_amount to pg +-- requires: roles +-- requires: schema_numerus +-- requires: quote_product +-- requires: quote_product_amount + +begin; + +set search_path to numerus, public; + +create or replace view quote_amount as +select quote_id + , sum(subtotal)::integer as subtotal + , sum(total)::integer as total +from quote_product +join quote_product_amount using (quote_product_id) +group by quote_id +; + +grant select on table quote_amount to invoicer; +grant select on table quote_amount to admin; + +commit; diff --git a/deploy/quote_product_amount.sql b/deploy/quote_product_amount.sql new file mode 100644 index 0000000..16f2536 --- /dev/null +++ b/deploy/quote_product_amount.sql @@ -0,0 +1,23 @@ +-- Deploy numerus:quote_product_amount to pg +-- requires: roles +-- requires: schema_numerus +-- requires: quote_product +-- requires: quote_product_tax + +begin; + +set search_path to numerus, public; + +create or replace view quote_product_amount as +select quote_product_id + , round(price * quantity * (1 - discount_rate))::integer as subtotal + , max(round(price * quantity * (1 - discount_rate))::integer) + coalesce(sum(round(round(price * quantity * (1 - discount_rate))::integer * tax_rate)::integer)::integer, 0) as total +from quote_product +left join quote_product_tax using (quote_product_id) +group by quote_product_id, price, quantity, discount_rate +; + +grant select on table quote_product_amount to invoicer; +grant select on table quote_product_amount to admin; + +commit; diff --git a/deploy/quote_tax_amount.sql b/deploy/quote_tax_amount.sql new file mode 100644 index 0000000..5266528 --- /dev/null +++ b/deploy/quote_tax_amount.sql @@ -0,0 +1,24 @@ +-- Deploy numerus:quote_tax_amount to pg +-- requires: roles +-- requires: schema_numerus +-- requires: quote_product +-- requires: quote_product_tax + +begin; + +set search_path to numerus, public; + +create or replace view quote_tax_amount as +select quote_id + , tax_id + , sum(round(round(price * quantity * (1 - discount_rate))::integer * tax_rate)::integer)::integer as amount +from quote_product +join quote_product_tax using (quote_product_id) +group by quote_id + , tax_id +; + +grant select on table quote_tax_amount to invoicer; +grant select on table quote_tax_amount to admin; + +commit; diff --git a/revert/compute_new_quote_amount.sql b/revert/compute_new_quote_amount.sql new file mode 100644 index 0000000..099349c --- /dev/null +++ b/revert/compute_new_quote_amount.sql @@ -0,0 +1,7 @@ +-- Revert numerus:compute_new_quote_amount from pg + +begin; + +drop function if exists numerus.compute_new_quote_amount(integer, numerus.new_quote_product[]); + +commit; diff --git a/revert/edit_quote.sql b/revert/edit_quote.sql new file mode 100644 index 0000000..91cab49 --- /dev/null +++ b/revert/edit_quote.sql @@ -0,0 +1,7 @@ +-- Revert numerus:edit_quote from pg + +begin; + +drop function if exists numerus.edit_quote(uuid, text, integer, text, text, integer, numerus.tag_name[], numerus.edited_quote_product[]); + +commit; diff --git a/revert/edited_quote_product.sql b/revert/edited_quote_product.sql new file mode 100644 index 0000000..93c6487 --- /dev/null +++ b/revert/edited_quote_product.sql @@ -0,0 +1,7 @@ +-- Revert numerus:edited_quote_product from pg + +begin; + +drop type if exists numerus.edited_quote_product; + +commit; diff --git a/revert/new_quote_amount.sql b/revert/new_quote_amount.sql new file mode 100644 index 0000000..ebbdc4a --- /dev/null +++ b/revert/new_quote_amount.sql @@ -0,0 +1,7 @@ +-- Revert numerus:new_quote_amount from pg + +begin; + +drop type if exists numerus.new_quote_amount; + +commit; diff --git a/revert/quote_amount.sql b/revert/quote_amount.sql new file mode 100644 index 0000000..1fe5f13 --- /dev/null +++ b/revert/quote_amount.sql @@ -0,0 +1,7 @@ +-- Revert numerus:quote_amount from pg + +begin; + +drop view if exists numerus.quote_amount; + +commit; diff --git a/revert/quote_product_amount.sql b/revert/quote_product_amount.sql new file mode 100644 index 0000000..5f39e5f --- /dev/null +++ b/revert/quote_product_amount.sql @@ -0,0 +1,7 @@ +-- Revert numerus:quote_product_amount from pg + +begin; + +drop view if exists numerus.quote_product_amount; + +commit; diff --git a/revert/quote_tax_amount.sql b/revert/quote_tax_amount.sql new file mode 100644 index 0000000..a5cc20c --- /dev/null +++ b/revert/quote_tax_amount.sql @@ -0,0 +1,7 @@ +-- Revert numerus:quote_tax_amount from pg + +begin; + +drop view if exists numerus.quote_tax_amount; + +commit; diff --git a/sqitch.plan b/sqitch.plan index dfdc81b..fb43d29 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -90,3 +90,10 @@ quote_number_counter [roles schema_numerus company] 2023-06-07T11:05:51Z jordi f next_quote_number [roles schema_numerus quote_number_counter] 2023-06-07T11:20:54Z jordi fita mas # Add function to retrieve the next quote number new_quote_product [schema_numerus discount_rate] 2023-06-07T11:36:37Z jordi fita mas # Add type for passing products to new quotes add_quote [roles schema_numerus quote company currency parse_price new_quote_product tax quote_product quote_payment_method quote_contact quote_product_product quote_product_tax next_quote_number tag_name] 2023-06-07T11:39:45Z jordi fita mas # Add function to create new quotes +quote_tax_amount [roles schema_numerus quote_product quote_product_tax] 2023-06-07T12:45:17Z jordi fita mas # Add add view for quote tax amount +quote_product_amount [roles schema_numerus quote_product quote_product_tax] 2023-06-07T12:48:58Z jordi fita mas # Add view for quote product subtotal and total +quote_amount [roles schema_numerus quote_product quote_product_amount] 2023-06-07T12:52:51Z jordi fita mas # Add view to compute subtotal and total for quotes +new_quote_amount [schema_numerus] 2023-06-07T12:57:45Z jordi fita mas # Add type to return when computing new quote amounts +compute_new_quote_amount [roles schema_numerus company tax new_quote_product new_quote_amount] 2023-06-07T13:00:07Z jordi fita mas # Add function to compute the subtotal, taxes, and total amounts for a new quotation +edited_quote_product [schema_numerus discount_rate] 2023-06-07T13:03:23Z jordi fita mas # Add type for passing products to edit quotations +edit_quote [roles schema_numerus quote currency parse_price edited_quote_product tax quote_contact quote_payment_method quote_product quote_product_tax quote_product_product tag_name] 2023-06-07T13:08:10Z jordi fita mas # Add function to edit quotations diff --git a/test/compute_new_quote_amount.sql b/test/compute_new_quote_amount.sql new file mode 100644 index 0000000..8645fe0 --- /dev/null +++ b/test/compute_new_quote_amount.sql @@ -0,0 +1,80 @@ +-- Test compute_new_quote_amount +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(14); + +set search_path to numerus, auth, public; + +select has_function('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]']); +select function_lang_is('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'plpgsql'); +select function_returns('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'new_quote_amount'); +select isnt_definer('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]']); +select volatility_is('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'stable'); +select function_privs_are('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'guest', array []::text[]); +select function_privs_are('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'invoicer', array ['EXECUTE']); +select function_privs_are('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'admin', array ['EXECUTE']); +select function_privs_are('numerus', 'compute_new_quote_amount', array ['integer', 'new_quote_product[]'], 'authenticator', array []::text[]); + +set client_min_messages to warning; +truncate tax cascade; +truncate tax_class cascade; +truncate payment_method cascade; +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, default_payment_method_id) +values (1, 'Company 1', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (111, 1, 'cash', 'cash') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into tax_class (tax_class_id, company_id, name) +values (11, 1, 'tax') +; + +insert into tax (tax_id, company_id, tax_class_id, name, rate) +values (2, 1, 11, 'IRPF -15 %', -0.15) + , (3, 1, 11, 'IVA 4 %', 0.04) + , (4, 1, 11, 'IVA 10 %', 0.10) + , (5, 1, 11, 'IVA 21 %', 0.21) +; + +select is( + compute_new_quote_amount(1, '{}'), + '(0.00,"{}",0.00)'::new_quote_amount +); + +select is( + compute_new_quote_amount(1, '{"(6,P,D,1.00,1,0.0,\"{2,5}\")","(6,P,D,2.00,2,0.1,{3})"}'), + '(4.60,"{{IRPF -15 %,-0.15},{IVA 4 %,0.14},{IVA 21 %,0.21}}",4.80)'::new_quote_amount +); + +select is( + compute_new_quote_amount(1, '{"(6,P,D,2.22,3,0.0,\"{2,4,5}\")","(6,P,D,3.33,4,0.2,{4})"}'), + '(17.32,"{{IRPF -15 %,-1.00},{IVA 10 %,1.74},{IVA 21 %,1.40}}",19.46)'::new_quote_amount +); + +select is( + compute_new_quote_amount(1, '{"(6,P,D,4.44,5,0.0,\"{4,5}\")","(6,P,D,5.55,6,0.1,\"{5,3}\")"}'), + '(52.17,"{{IVA 4 %,1.20},{IVA 10 %,2.22},{IVA 21 %,10.95}}",66.54)'::new_quote_amount +); + +select is( + compute_new_quote_amount(1, '{"(6,P,D,7.77,8,0.0,\"{}\")"}'), + '(62.16,"{}",62.16)'::new_quote_amount +); + +select * +from finish(); + +rollback; diff --git a/test/edit_quote.sql b/test/edit_quote.sql new file mode 100644 index 0000000..497b408 --- /dev/null +++ b/test/edit_quote.sql @@ -0,0 +1,173 @@ +-- Test edit_quote +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(16); + +set search_path to auth, numerus, public; + +select has_function('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]']); +select function_lang_is('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'plpgsql'); +select function_returns('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'uuid'); +select isnt_definer('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]']); +select volatility_is('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'volatile'); +select function_privs_are('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'guest', array []::text[]); +select function_privs_are('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'invoicer', array ['EXECUTE']); +select function_privs_are('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'admin', array ['EXECUTE']); +select function_privs_are('numerus', 'edit_quote', array ['uuid', 'text', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'edited_quote_product[]'], 'authenticator', array []::text[]); + + +set client_min_messages to warning; +truncate quote_product_tax cascade; +truncate quote_product cascade; +truncate quote_payment_method cascade; +truncate quote_contact cascade; +truncate quote cascade; +truncate contact cascade; +truncate product cascade; +truncate tax cascade; +truncate tax_class cascade; +truncate payment_method cascade; +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, default_payment_method_id) +values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (111, 1, 'cash', 'cash') + , (112, 1, 'bank', 'send money to my bank account') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into tax_class (tax_class_id, company_id, name) +values (11, 1, '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) +; + +insert into product (product_id, company_id, name, price) +values ( 7, 1, 'Product 1.1', 1212) + , ( 8, 1, 'Product 2.2', 2424) + , ( 9, 1, 'Product 3.3', 3636) +; + +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') +; + +insert into quote (quote_id, company_id, slug, quote_number, quote_date, currency_code, tags) +values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'QUO1', '2023-03-10', 'EUR', '{tag1}') + , (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'QUO2', '2023-03-09', 'EUR', '{tag2}') + , (17, 1, '0b899316-f7d0-4175-a9d5-cea855844716', 'QUO3', '2023-03-11', 'EUR', '{}') +; + +insert into quote_payment_method (quote_id, payment_method_id) +values (15, 111) + , (16, 111) +; + +insert into quote_contact (quote_id, contact_id) +values (15, 12) + , (16, 13) +; + +insert into quote_product (quote_product_id, quote_id, name, price) +values (19, 15, 'P1.0', 1100) + , (20, 15, 'P2.0', 2200) + , (21, 16, 'P1.1', 1111) + , (22, 16, 'P2.1', 2211) + , (23, 17, 'P3.1', 3311) +; + +insert into quote_product_product (quote_product_id, product_id) +values (19, 7) + , (20, 8) + , (21, 7) + , (22, 8) +; + +insert into quote_product_tax (quote_product_id, tax_id, tax_rate) +values (19, 4, 0.21) + , (20, 4, 0.21) + , (21, 3, -0.07) + , (21, 4, 0.21) + , (22, 3, -0.15) +; + +select lives_ok( + $$ select edit_quote('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'accepted', null, 'Terms 1', 'Notes 1', 112, array['tag1'], '{"(20,,p1.0,D1,11.01,2,0.50,{4})","(,,p1.3,D3,33.33,3,0.05,{3})"}') $$, + 'Should be able to edit the first invoice' +); + +select lives_ok( + $$ select edit_quote('b57b980b-247b-4be4-a0b7-03a7819c53ae', 'sent', 12, 'Terms 2', 'Notes 2', null, array['tag1', 'tag3'], '{"(21,7,P1.1,,11.11,1,0.0,{3})","(22,8,p2.1,D2,24.00,3,0.75,\"{3,4}\")","(,9,p3.3,,36.36,2,0.05,{4})"}') $$, + 'Should be able to edit the second quote' +); + +select lives_ok( + $$ select edit_quote('0b899316-f7d0-4175-a9d5-cea855844716', 'rejected', 13, '', '', 111, '{}', '{"(23,,p3.1,,41.41,1,0.0,{})"}') $$, + 'Should be able to edit the third quote' +); + +select bag_eq( + $$ select quote_number, quote_date, contact_id, quote_status, terms_and_conditions, notes, tags, payment_method_id from quote left join quote_contact using (quote_id) left join quote_payment_method using (quote_id) $$, + $$ values ('QUO1', '2023-03-10'::date, null, 'accepted', 'Terms 1', 'Notes 1', '{tag1}'::tag_name[], 112) + , ('QUO2', '2023-03-09'::date, 12, 'sent', 'Terms 2', 'Notes 2', '{tag1,tag3}'::tag_name[], null) + , ('QUO3', '2023-03-11'::date, 13, 'rejected', '', '', '{}'::tag_name[], 111) + $$, + 'Should have updated all quotes' +); + +select bag_eq( + $$ select quote_number, name, description, price, quantity, discount_rate from quote_product join quote using (quote_id) $$, + $$ values ('QUO1', 'p1.0', 'D1', 1101, 2, 0.50) + , ('QUO1', 'p1.3', 'D3', 3333, 3, 0.05) + , ('QUO2', 'P1.1', '', 1111, 1, 0.00) + , ('QUO2', 'p2.1', 'D2', 2400, 3, 0.75) + , ('QUO2', 'p3.3', '', 3636, 2, 0.05) + , ('QUO3', 'p3.1', '', 4141, 1, 0.00) + $$, + 'Should have updated all existing quote products, added new ones, and removed the ones not give to the function' +); + +select bag_eq( + $$ select quote_number, product_id, name from quote_product left join quote_product_product using (quote_product_id) join quote using (quote_id) $$, + $$ values ('QUO1', NULL, 'p1.0') + , ('QUO1', NULL, 'p1.3') + , ('QUO2', 7, 'P1.1') + , ('QUO2', 8, 'p2.1') + , ('QUO2', 9, 'p3.3') + , ('QUO3', NULL, 'p3.1') + $$, + 'Should have updated all existing quote products id, added new ones, and removed the ones not give to the function' +); + +select bag_eq( + $$ select quote_number, name, tax_id, tax_rate from quote_product_tax join quote_product using (quote_product_id) join quote using (quote_id) $$, + $$ values ('QUO1', 'p1.0', 4, 0.21) + , ('QUO1', 'p1.3', 3, -0.15) + , ('QUO2', 'P1.1', 3, -0.15) + , ('QUO2', 'p2.1', 3, -0.15) + , ('QUO2', 'p2.1', 4, 0.21) + , ('QUO2', 'p3.3', 4, 0.21) + $$, + 'Should have updated all quote product taxes, added new ones, and removed the ones not given to the function' +); + +select * +from finish(); + +rollback; diff --git a/test/edited_quote_product.sql b/test/edited_quote_product.sql new file mode 100644 index 0000000..ec33000 --- /dev/null +++ b/test/edited_quote_product.sql @@ -0,0 +1,26 @@ +-- Test edited_quote_product +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(10); + +set search_path to numerus, public; + +select has_composite('numerus', 'edited_quote_product', 'Composite type numerus.edited_quote_product should exist'); +select columns_are('numerus', 'edited_quote_product', array['quote_product_id', 'product_id', 'name', 'description', 'price', 'quantity', 'discount_rate', 'tax']); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'quote_product_id'::name, 'integer'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'product_id'::name, 'integer'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'name'::name, 'text'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'description'::name, 'text'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'price'::name, 'text'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'quantity'::name, 'integer'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'discount_rate'::name, 'discount_rate'); +select col_type_is('numerus'::name, 'edited_quote_product'::name, 'tax'::name, 'integer[]'); + +select * +from finish(); + +rollback; diff --git a/test/new_quote_amount.sql b/test/new_quote_amount.sql new file mode 100644 index 0000000..36c3881 --- /dev/null +++ b/test/new_quote_amount.sql @@ -0,0 +1,21 @@ +-- Test new_quote_amount +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(5); + +set search_path to numerus, public; + +select has_composite('numerus', 'new_quote_amount', 'Composite type numerus.new_quote_amount should exist'); +select columns_are('numerus', 'new_quote_amount', array['subtotal', 'taxes', 'total']); +select col_type_is('numerus'::name, 'new_quote_amount'::name, 'subtotal'::name, 'text'); +select col_type_is('numerus'::name, 'new_quote_amount'::name, 'taxes'::name, 'text[]'); +select col_type_is('numerus'::name, 'new_quote_amount'::name, 'total'::name, 'text'); + +select * +from finish(); + +rollback; diff --git a/test/quote_amount.sql b/test/quote_amount.sql new file mode 100644 index 0000000..81624cd --- /dev/null +++ b/test/quote_amount.sql @@ -0,0 +1,110 @@ +-- Test quote_amount +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(12); + +set search_path to numerus, auth, public; + +select has_view('quote_amount'); +select table_privs_are('quote_amount', 'guest', array[]::text[]); +select table_privs_are('quote_amount', 'invoicer', array['SELECT']); +select table_privs_are('quote_amount', 'admin', array['SELECT']); +select table_privs_are('quote_amount', 'authenticator', array[]::text[]); + +select has_column('quote_amount', 'quote_id'); +select col_type_is('quote_amount', 'quote_id', 'integer'); + +select has_column('quote_amount', 'subtotal'); +select col_type_is('quote_amount', 'subtotal', 'integer'); + +select has_column('quote_amount', 'total'); +select col_type_is('quote_amount', 'total', 'integer'); + + +set client_min_messages to warning; +truncate quote_product_tax cascade; +truncate quote_product cascade; +truncate quote cascade; +truncate contact cascade; +truncate tax cascade; +truncate tax_class cascade; +truncate payment_method cascade; +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, default_payment_method_id) +values (1, 'Company 1', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (111, 1, 'cash', 'cash') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into tax_class (tax_class_id, company_id, name) +values (11, 1, 'tax') +; + +insert into tax (tax_id, company_id, tax_class_id, name, rate) +values (2, 1, 11, 'IRPF -15 %', -0.15) + , (3, 1, 11, 'IVA 4 %', 0.04) + , (4, 1, 11, 'IVA 10 %', 0.10) + , (5, 1, 11, 'IVA 21 %', 0.21) +; + +insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code) +values (7, 1, 'Contact', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES') +; + +insert into quote (quote_id, company_id, quote_number, quote_date, currency_code) +values ( 8, 1, 'I1', current_date, 'EUR') + , ( 9, 1, 'I2', current_date, 'EUR') + , (10, 1, 'I3', current_date, 'EUR') + , (11, 1, 'I4', current_date, 'EUR') +; + +insert into quote_product (quote_product_id, quote_id, name, price, quantity, discount_rate) +values (12, 8, 'P', 100, 1, 0.0) + , (13, 8, 'P', 200, 2, 0.1) + , (14, 9, 'P', 222, 3, 0.0) + , (15, 9, 'P', 333, 4, 0.2) + , (16, 10, 'P', 444, 5, 0.0) + , (17, 10, 'P', 555, 6, 0.1) + , (18, 11, 'P', 777, 8, 0.0) +; + +insert into quote_product_tax (quote_product_id, tax_id, tax_rate) +values (12, 2, -0.15) + , (12, 5, 0.21) + , (13, 3, 0.04) + , (14, 4, 0.10) + , (14, 5, 0.21) + , (14, 2, -0.07) + , (15, 4, 0.10) + , (16, 4, 0.10) + , (16, 5, 0.21) + , (17, 5, 0.21) + , (17, 3, 0.04) +; + +select bag_eq( + $$ select quote_id, subtotal, total from quote_amount $$, + $$ values ( 8, 460, 480) + , ( 9, 1732, 1999) + , (10, 5217, 6654) + , (11, 6216, 6216) + $$, + 'Should compute the amount for all taxes in the quoted products.' +); + +select * +from finish(); + +rollback; diff --git a/test/quote_product_amount.sql b/test/quote_product_amount.sql new file mode 100644 index 0000000..f5c6426 --- /dev/null +++ b/test/quote_product_amount.sql @@ -0,0 +1,108 @@ +-- Test quote_product_amount +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(12); + +set search_path to numerus, auth, public; + +select has_view('quote_product_amount'); +select table_privs_are('quote_product_amount', 'guest', array[]::text[]); +select table_privs_are('quote_product_amount', 'invoicer', array['SELECT']); +select table_privs_are('quote_product_amount', 'admin', array['SELECT']); +select table_privs_are('quote_product_amount', 'authenticator', array[]::text[]); + +select has_column('quote_product_amount', 'quote_product_id'); +select col_type_is('quote_product_amount', 'quote_product_id', 'integer'); + +select has_column('quote_product_amount', 'subtotal'); +select col_type_is('quote_product_amount', 'subtotal', 'integer'); + +select has_column('quote_product_amount', 'total'); +select col_type_is('quote_product_amount', 'total', 'integer'); + + +set client_min_messages to warning; +truncate quote_product_tax cascade; +truncate quote_product cascade; +truncate quote cascade; +truncate tax cascade; +truncate tax_class cascade; +truncate payment_method cascade; +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, default_payment_method_id) +values (1, 'Company 1', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (111, 1, 'cash', 'cash') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into tax_class (tax_class_id, company_id, name) +values (11, 1, 'tax') +; + +insert into tax (tax_id, company_id, tax_class_id, name, rate) +values (2, 1, 11, 'IRPF -15 %', -0.15) + , (3, 1, 11, 'IVA 4 %', 0.04) + , (4, 1, 11, 'IVA 10 %', 0.10) + , (5, 1, 11, 'IVA 21 %', 0.21) +; + +insert into quote (quote_id, company_id, quote_number, quote_date, currency_code) +values ( 8, 1, 'I1', current_date, 'EUR') + , ( 9, 1, 'I2', current_date, 'EUR') + , (10, 1, 'I3', current_date, 'EUR') + , (11, 1, 'I4', current_date, 'EUR') +; + +insert into quote_product (quote_product_id, quote_id, name, price, quantity, discount_rate) +values (12, 8, 'P', 100, 1, 0.0) + , (13, 8, 'P', 200, 2, 0.1) + , (14, 9, 'P', 222, 3, 0.0) + , (15, 9, 'P', 333, 4, 0.2) + , (16, 10, 'P', 444, 5, 0.0) + , (17, 10, 'P', 555, 6, 0.1) + , (18, 11, 'P', 777, 8, 0.0) +; + +insert into quote_product_tax (quote_product_id, tax_id, tax_rate) +values (12, 2, -0.15) + , (12, 5, 0.21) + , (13, 3, 0.04) + , (14, 4, 0.10) + , (14, 5, 0.21) + , (14, 2, -0.07) + , (15, 4, 0.10) + , (16, 4, 0.10) + , (16, 5, 0.21) + , (17, 5, 0.21) + , (17, 3, 0.04) +; + +select bag_eq( + $$ select quote_product_id, subtotal, total from quote_product_amount $$, + $$ values (12, 100, 106) + , (13, 360, 374) + , (14, 666, 826) + , (15, 1066, 1173) + , (16, 2220, 2908) + , (17, 2997, 3746) + , (18, 6216, 6216) + $$, + 'Should compute the subtotal and total for all products.' +); + +select * +from finish(); + +rollback; diff --git a/test/quote_product_tax.sql b/test/quote_product_tax.sql index 481669e..cb305d8 100644 --- a/test/quote_product_tax.sql +++ b/test/quote_product_tax.sql @@ -40,7 +40,7 @@ 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 quote cascade; truncate tax cascade; truncate tax_class cascade; truncate company_user cascade; diff --git a/test/quote_tax_amount.sql b/test/quote_tax_amount.sql new file mode 100644 index 0000000..42331d9 --- /dev/null +++ b/test/quote_tax_amount.sql @@ -0,0 +1,110 @@ +-- Test quote_tax_amount +set client_min_messages to warning; +create extension if not exists pgtap; +reset client_min_messages; + +begin; + +select plan(12); + +set search_path to numerus, auth, public; + +select has_view('quote_tax_amount'); +select table_privs_are('quote_tax_amount', 'guest', array[]::text[]); +select table_privs_are('quote_tax_amount', 'invoicer', array['SELECT']); +select table_privs_are('quote_tax_amount', 'admin', array['SELECT']); +select table_privs_are('quote_tax_amount', 'authenticator', array[]::text[]); + +select has_column('quote_tax_amount', 'quote_id'); +select col_type_is('quote_tax_amount', 'quote_id', 'integer'); + +select has_column('quote_tax_amount', 'tax_id'); +select col_type_is('quote_tax_amount', 'tax_id', 'integer'); + +select has_column('quote_tax_amount', 'amount'); +select col_type_is('quote_tax_amount', 'amount', 'integer'); + + +set client_min_messages to warning; +truncate quote_product_tax cascade; +truncate quote_product cascade; +truncate quote cascade; +truncate tax cascade; +truncate tax_class cascade; +truncate payment_method cascade; +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, default_payment_method_id) +values (1, 'Company 1', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111) +; + +insert into payment_method (payment_method_id, company_id, name, instructions) +values (111, 1, 'cash', 'cash') +; + +set constraints "company_default_payment_method_id_fkey" immediate; + +insert into tax_class (tax_class_id, company_id, name) +values (11, 1, 'tax') +; + +insert into tax (tax_id, company_id, tax_class_id, name, rate) +values (2, 1, 11, 'IRPF -15 %', -0.15) + , (3, 1, 11, 'IVA 4 %', 0.04) + , (4, 1, 11, 'IVA 10 %', 0.10) + , (5, 1, 11, 'IVA 21 %', 0.21) +; + +insert into quote (quote_id, company_id, quote_number, quote_date, currency_code) +values ( 8, 1, 'I1', current_date, 'EUR') + , ( 9, 1, 'I2', current_date, 'EUR') + , (10, 1, 'I3', current_date, 'EUR') + , (11, 1, 'I4', current_date, 'EUR') +; + +insert into quote_product (quote_product_id, quote_id, name, price, quantity, discount_rate) +values (12, 8, 'P', 100, 1, 0.0) + , (13, 8, 'P', 200, 2, 0.1) + , (14, 9, 'P', 222, 3, 0.0) + , (15, 9, 'P', 333, 4, 0.2) + , (16, 10, 'P', 444, 5, 0.0) + , (17, 10, 'P', 555, 6, 0.1) + , (18, 11, 'P', 777, 8, 0.0) +; + +insert into quote_product_tax (quote_product_id, tax_id, tax_rate) +values (12, 2, -0.15) + , (12, 5, 0.21) + , (13, 3, 0.04) + , (14, 4, 0.10) + , (14, 5, 0.21) + , (14, 2, -0.07) + , (15, 4, 0.10) + , (16, 4, 0.10) + , (16, 5, 0.21) + , (17, 5, 0.21) + , (17, 3, 0.04) +; + +select bag_eq( + $$ select quote_id, tax_id, amount from quote_tax_amount $$, + $$ values ( 8, 2, -15) + , ( 8, 3, 14) + , ( 8, 5, 21) + , ( 9, 2, -47) + , ( 9, 4, 174) + , ( 9, 5, 140) + , (10, 3, 120) + , (10, 4, 222) + , (10, 5, 1095) + $$, + 'Should compute the amount for all taxes in the quoted products.' +); + +select * +from finish(); + +rollback; diff --git a/verify/compute_new_quote_amount.sql b/verify/compute_new_quote_amount.sql new file mode 100644 index 0000000..a76cb33 --- /dev/null +++ b/verify/compute_new_quote_amount.sql @@ -0,0 +1,7 @@ +-- Verify numerus:compute_new_quote_amount on pg + +begin; + +select has_function_privilege('numerus.compute_new_quote_amount(integer, numerus.new_quote_product[])', 'execute'); + +rollback; diff --git a/verify/edit_quote.sql b/verify/edit_quote.sql new file mode 100644 index 0000000..926f94a --- /dev/null +++ b/verify/edit_quote.sql @@ -0,0 +1,7 @@ +-- Verify numerus:edit_quote on pg + +begin; + +select has_function_privilege('numerus.edit_quote(uuid, text, integer, text, text, integer, numerus.tag_name[], numerus.edited_quote_product[])', 'execute'); + +rollback; diff --git a/verify/edited_quote_product.sql b/verify/edited_quote_product.sql new file mode 100644 index 0000000..72d36b8 --- /dev/null +++ b/verify/edited_quote_product.sql @@ -0,0 +1,7 @@ +-- Verify numerus:edited_quote_product on pg + +begin; + +select pg_catalog.has_type_privilege('numerus.edited_quote_product', 'usage'); + +rollback; diff --git a/verify/new_quote_amount.sql b/verify/new_quote_amount.sql new file mode 100644 index 0000000..ff021c9 --- /dev/null +++ b/verify/new_quote_amount.sql @@ -0,0 +1,7 @@ +-- Verify numerus:new_quote_amount on pg + +begin; + +select pg_catalog.has_type_privilege('numerus.new_invoice_amount', 'usage'); + +rollback; diff --git a/verify/quote_amount.sql b/verify/quote_amount.sql new file mode 100644 index 0000000..6623f7b --- /dev/null +++ b/verify/quote_amount.sql @@ -0,0 +1,11 @@ +-- Verify numerus:quote_amount on pg + +begin; + +select quote_id + , subtotal + , total +from numerus.quote_amount +where false; + +rollback; diff --git a/verify/quote_product_amount.sql b/verify/quote_product_amount.sql new file mode 100644 index 0000000..64daf05 --- /dev/null +++ b/verify/quote_product_amount.sql @@ -0,0 +1,11 @@ +-- Verify numerus:quote_product_amount on pg + +begin; + +select quote_product_id + , subtotal + , total +from numerus.quote_product_amount +where false; + +rollback; diff --git a/verify/quote_tax_amount.sql b/verify/quote_tax_amount.sql new file mode 100644 index 0000000..b5d91c0 --- /dev/null +++ b/verify/quote_tax_amount.sql @@ -0,0 +1,11 @@ +-- Verify numerus:quote_tax_amount on pg + +begin; + +select quote_id + , tax_id + , amount +from numerus.quote_tax_amount +where false; + +rollback;