numerus/deploy/add_invoice.sql

68 lines
1.9 KiB
MySQL
Raw Normal View History

2023-02-16 22:09:10 +00:00
-- 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;