numerus/deploy/edit_invoice.sql

120 lines
3.5 KiB
MySQL
Raw Normal View History

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
-- 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[];
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;
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
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;