numerus/deploy/add_invoice.sql

91 lines
2.7 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
-- requires: next_invoice_number
-- requires: tag_name
-- requires: tag
-- requires: invoice_tag
2023-02-16 22:09:10 +00:00
begin;
set search_path to numerus, public;
create or replace function add_invoice(company integer, invoice_number text, invoice_date date, contact_id integer, notes text, payment_method_id integer, tags tag_name[], products new_invoice_product[]) returns uuid as
2023-02-16 22:09:10 +00:00
$$
declare
iid integer;
pslug uuid;
product new_invoice_product;
ccode text;
ipid integer;
begin
if invoice_number is null or length(trim(invoice_number)) = 0 then
invoice_number = next_invoice_number(company, invoice_date);
end if;
2023-03-05 17:50:57 +00:00
insert into invoice (company_id, invoice_number, invoice_date, contact_id, notes, currency_code, payment_method_id)
select company_id
2023-02-16 22:09:10 +00:00
, invoice_number
, invoice_date
, contact_id
, notes
, currency_code
2023-03-05 17:50:57 +00:00
, add_invoice.payment_method_id
2023-02-16 22:09:10 +00:00
from company
where company.company_id = add_invoice.company
2023-02-16 22:09:10 +00:00
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;
if array_length(tags, 1) > 0 then
insert into tag (company_id, name)
select add_invoice.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 = add_invoice.company and tag.name = new_tag.name
;
end if;
2023-02-16 22:09:10 +00:00
return pslug;
end;
$$
language plpgsql;
revoke execute on function add_invoice(integer, text, date, integer, text, integer, tag_name[], new_invoice_product[]) from public;
grant execute on function add_invoice(integer, text, date, integer, text, integer, tag_name[], new_invoice_product[]) to invoicer;
grant execute on function add_invoice(integer, text, date, integer, text, integer, tag_name[], new_invoice_product[]) to admin;
2023-02-16 22:09:10 +00:00
commit;