Add function to edit invoices

This commit is contained in:
jordi fita mas 2023-03-11 20:58:20 +01:00
parent 2bc05e948c
commit 0cd0fb1bb8
10 changed files with 349 additions and 1 deletions

109
deploy/edit_invoice.sql Normal file
View File

@ -0,0 +1,109 @@
-- Deploy numerus:edit_invoice to pg
-- requires: schema_numerus
-- requires: invoice
-- requires: currency
-- requires: parse_price
-- requires: edited_invoice_product
-- requires: tax
-- requires: invoice_product
-- requires: invoice_product_tax
-- requires: tag_name
-- requires: tag
-- requires: invoice_tag
begin;
set search_path to numerus, public;
create or replace function edit_invoice(invoice_slug uuid, invoice_status text, contact_id integer, notes text, payment_method_id integer, tags tag_name[], products edited_invoice_product[]) returns uuid as
$$
declare
iid integer;
products_to_keep integer[];
company integer;
ccode text;
product edited_invoice_product;
ipid integer;
begin
update invoice
set contact_id = edit_invoice.contact_id
, invoice_status = edit_invoice.invoice_status
, notes = edit_invoice.notes
, payment_method_id = edit_invoice.payment_method_id
where slug = invoice_slug
returning invoice_id, company_id, currency_code
into iid, company, ccode
;
if iid is null then
return null;
end if;
foreach product in array products
loop
if product.invoice_product_id is null then
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;
else
ipid := product.invoice_product_id;
update invoice_product
set product_id = product.product_id
, 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 invoice_product_id = ipid
and currency_code = ccode;
end if;
products_to_keep := array_append(products_to_keep, ipid);
delete from invoice_product_tax where invoice_product_id = 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;
delete from invoice_product where invoice_id = iid and not (invoice_product_id = any(products_to_keep));
delete from invoice_tag where invoice_id = iid;
if array_length(tags, 1) > 0 then
insert into tag (company_id, name)
select company, new_tag.name
from unnest (tags) as new_tag(name)
on conflict (company_id, name) do nothing
;
insert into invoice_tag (invoice_id, tag_id)
select iid, tag_id
from tag
join unnest (tags) as new_tag(name) on company_id = company and tag.name = new_tag.name
;
end if;
return invoice_slug;
end;
$$
language plpgsql;
revoke execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) from public;
grant execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) to invoicer;
grant execute on function edit_invoice(uuid, text, integer, text, integer, tag_name[], edited_invoice_product[]) to admin;
commit;

View File

@ -0,0 +1,20 @@
-- Deploy numerus:edited_invoice_product to pg
-- requires: schema_numerus
-- requires: discount_rate
begin;
set search_path to numerus, public;
create type edited_invoice_product as
( invoice_product_id integer
, product_id integer
, name text
, description text
, price text
, quantity integer
, discount_rate discount_rate
, tax integer[]
);
commit;

View File

@ -1,5 +1,6 @@
-- Deploy numerus:new_invoice_product to pg
-- requires: schema_numerus
-- requires: discount_rate
begin;

7
revert/edit_invoice.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert numerus:edit_invoice from pg
begin;
drop function if exists numerus.edit_invoice(uuid, text, integer, text, integer, numerus.tag_name[], numerus.edited_invoice_product[]);
commit;

View File

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

View File

@ -55,7 +55,7 @@ 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 <jordi@tandem.blog> # 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 <jordi@tandem.blog> # Add function to edit 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 discount_rate] 2023-02-16T21:06:01Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to 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
tag_name [schema_numerus] 2023-03-10T11:06:11Z jordi fita mas <jordi@tandem.blog> # Add domain for tag names
@ -67,3 +67,5 @@ invoice_product_amount [schema_numerus invoice_product invoice_product_tax] 2023
invoice_amount [schema_numerus invoice_product invoice_product_amount] 2023-02-22T12:58:46Z jordi fita mas <jordi@tandem.blog> # Add view to compute subtotal and total for invoices
new_invoice_amount [schema_numerus] 2023-02-23T12:08:25Z jordi fita mas <jordi@tandem.blog> # Add type to return when computing new invoice amounts
compute_new_invoice_amount [schema_numerus company currency tax new_invoice_product new_invoice_amount] 2023-02-23T12:20:13Z jordi fita mas <jordi@tandem.blog> # Add function to compute the subtotal, taxes, and total amounts for a new invoice
edited_invoice_product [schema_numerus discount_rate] 2023-03-11T19:22:24Z jordi fita mas <jordi@tandem.blog> # Add typo for passing products to edited invoices
edit_invoice [schema_numerus invoice currency parse_price edited_invoice_product tax invoice_product invoice_product_tax tag_name tag invoice_tag] 2023-03-11T18:30:50Z jordi fita mas <jordi@tandem.blog> # Add function to edit invoices

161
test/edit_invoice.sql Normal file
View File

@ -0,0 +1,161 @@
-- Test edit_invoice
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_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]']);
select function_lang_is('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'plpgsql');
select function_returns('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'uuid');
select isnt_definer('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]']);
select volatility_is('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'volatile');
select function_privs_are('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'guest', array []::text[]);
select function_privs_are('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'edit_invoice', array ['uuid', 'text', 'integer', 'text', 'integer', 'tag_name[]', 'edited_invoice_product[]'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate invoice_tag cascade;
truncate tag cascade;
truncate invoice_product_tax cascade;
truncate invoice_product cascade;
truncate invoice 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 tag (tag_id, company_id, name)
values (10, 1, 'tag1')
, (11, 1, 'tag2')
;
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 invoice (invoice_id, company_id, slug, invoice_number, invoice_date, contact_id, payment_method_id, currency_code)
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-03-10', 12, 111, 'EUR')
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-03-09', 13, 111, 'EUR')
;
insert into invoice_tag (invoice_id, tag_id)
values (15, 10)
, (16, 11)
;
insert into invoice_product (invoice_product_id, invoice_id, product_id, name, price)
values (19, 15, 7, 'P1.0', 1100)
, (20, 15, 8, 'P2.0', 2200)
, (21, 16, 7, 'P1.1', 1111)
, (22, 16, 8, 'P2.1', 2211)
;
insert into invoice_product_tax (invoice_product_id, tax_id, tax_rate)
values (20, 4, 0.21)
, (21, 3, -0.07)
, (21, 4, 0.21)
, (22, 3, -0.15)
;
select lives_ok(
$$ select edit_invoice('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'paid', 13, 'Notes 1', 112, array['tag1'], '{"(20,7,p1.0,D1,11.01,2,0.50,{4})"}') $$,
'Should be able to edit the first invoice'
);
select lives_ok(
$$ select edit_invoice('b57b980b-247b-4be4-a0b7-03a7819c53ae', 'sent', 12, 'Notes 2', 111, 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 invoice'
);
select bag_eq(
$$ select invoice_number, invoice_date, contact_id, invoice_status, notes, payment_method_id from invoice $$,
$$ values ('INV1', '2023-03-10'::date, 13, 'paid', 'Notes 1', 112)
, ('INV2', '2023-03-09'::date, 12, 'sent', 'Notes 2', 111)
$$,
'Should have updated 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 ('INV1', 7, 'p1.0', 'D1', 1101, 2, 0.50)
, ('INV2', 7, 'P1.1', '', 1111, 1, 0.00)
, ('INV2', 8, 'p2.1', 'D2', 2400, 3, 0.75)
, ('INV2', 9, 'p3.3', '', 3636, 2, 0.05)
$$,
'Should have updated all existing invoice products, added new ones, and removed the ones not give to the function'
);
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 ('INV1', 7, 4, 0.21)
, ('INV2', 7, 3, -0.15)
, ('INV2', 8, 3, -0.15)
, ('INV2', 8, 4, 0.21)
, ('INV2', 9, 4, 0.21)
$$,
'Should have updated all invoice product taxes, added new ones, and removed the ones not given to the function'
);
select bag_eq(
$$ select company_id, name from tag $$,
$$ values (1, 'tag1')
, (1, 'tag2')
, (1, 'tag3')
$$,
'Should have added all new tags'
);
select bag_eq(
$$ select invoice_number, tag.name from invoice_tag join invoice using (invoice_id) join tag using (tag_id) $$,
$$ values ('INV1', 'tag1')
, ('INV2', 'tag1')
, ('INV2', 'tag3')
$$,
'Should have assigned the tags to invoices'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,27 @@
-- Test edited_invoice_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_invoice_product', 'Composite type numerus.edited_invoice_product should exist');
select columns_are('numerus', 'edited_invoice_product', array['invoice_product_id', 'product_id', 'name', 'description', 'price', 'quantity', 'discount_rate', 'tax']);
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'invoice_product_id'::name, 'integer');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'product_id'::name, 'integer');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'name'::name, 'text');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'description'::name, 'text');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'price'::name, 'text');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'quantity'::name, 'integer');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'discount_rate'::name, 'discount_rate');
select col_type_is('numerus'::name, 'edited_invoice_product'::name, 'tax'::name, 'integer[]');
select *
from finish();
rollback;

7
verify/edit_invoice.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify numerus:edit_invoice on pg
begin;
select has_function_privilege('numerus.edit_invoice(uuid, text, integer, text, integer, numerus.tag_name[], numerus.edited_invoice_product[])', 'execute');
rollback;

View File

@ -0,0 +1,7 @@
-- Verify numerus:edited_invoice_product on pg
begin;
select pg_catalog.has_type_privilege('numerus.edited_invoice_product', 'usage');
rollback;