2023-03-11 19:58:20 +00:00
|
|
|
-- 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
|
Add SQL and helper PL/pgSQL functions to tag invoices
We plan to tag also contacts and products using the same tag relation,
but different invoice_tag, contact_tag, and product_tag relations for
each one. However, the logic is the same for all three, hence it makes
more sense to put it into a PL/pgSQL with dynamic SQL. Moreover, the
SQL for tagging in add_invoice and edit_invoice where almost exactly
the same, the only difference was deleting the existing tags when
editing.
I do not execute the tag_relation function in its test suite because
by itself it does nothing without supporting invoice_tag, contact_tag,
or any such relation, so it is being tested in the suite for
tag_invoice.
2023-03-25 18:34:27 +00:00
|
|
|
-- requires: tag_invoice
|
2023-03-11 19:58:20 +00:00
|
|
|
|
|
|
|
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[];
|
2023-03-13 13:32:02 +00:00
|
|
|
products_to_delete integer[];
|
2023-03-11 19:58:20 +00:00
|
|
|
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;
|
|
|
|
|
2023-03-13 13:32:02 +00:00
|
|
|
select array_agg(invoice_product_id)
|
|
|
|
into products_to_delete
|
|
|
|
from invoice_product
|
|
|
|
where invoice_id = iid
|
|
|
|
and not (invoice_product_id = any(products_to_keep));
|
|
|
|
|
|
|
|
if array_length(products_to_delete, 1) > 0 then
|
|
|
|
delete from invoice_product_tax where invoice_product_id = any(products_to_delete);
|
|
|
|
delete from invoice_product where invoice_product_id = any(products_to_delete);
|
|
|
|
end if;
|
2023-03-11 19:58:20 +00:00
|
|
|
|
Add SQL and helper PL/pgSQL functions to tag invoices
We plan to tag also contacts and products using the same tag relation,
but different invoice_tag, contact_tag, and product_tag relations for
each one. However, the logic is the same for all three, hence it makes
more sense to put it into a PL/pgSQL with dynamic SQL. Moreover, the
SQL for tagging in add_invoice and edit_invoice where almost exactly
the same, the only difference was deleting the existing tags when
editing.
I do not execute the tag_relation function in its test suite because
by itself it does nothing without supporting invoice_tag, contact_tag,
or any such relation, so it is being tested in the suite for
tag_invoice.
2023-03-25 18:34:27 +00:00
|
|
|
perform tag_invoice(company, iid, tags);
|
2023-03-11 19:58:20 +00:00
|
|
|
|
|
|
|
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;
|