numerus/deploy/update_invoice_collection_s...

52 lines
1.7 KiB
PL/PgSQL

-- Deploy numerus:update_invoice_collection_status to pg
-- requires: roles
-- requires: schema_numerus
-- requires: invoice
-- requires: payment
-- requires: invoice_payment
-- requires: invoice_amount
-- requires: available_invoice_status
-- requires: available_payment_status
begin;
set search_path to numerus, public;
create or replace function update_invoice_collection_status(cid integer, iid integer, amount_cents integer) returns void as
$$
update payment
set payment_status = case
when (invoice_amount.total > 0 and invoice_amount.total > amount_cents) or (invoice_amount.total < 0 and invoice_amount.total < amount_cents) or exists (select 1 from invoice_payment as ic where ic.invoice_id = invoice_amount.invoice_id and payment_id <> cid) then 'partial'
else 'complete' end
from invoice_amount
where invoice_id = iid
and payment_id = cid
;
update invoice
set invoice_status = case
when (total_amount > 0 and collected_amount >= total_amount) or (total_amount < 0 and collected_amount <= total_amount) then 'paid'
when collected_amount = 0 then 'created'
else 'partial' end
from (
select coalesce(sum(payment.amount), 0) as collected_amount
from invoice_payment
join payment using (payment_id)
where invoice_payment.invoice_id = iid
) as collection,
(
select total as total_amount
from invoice_amount
where invoice_id = iid
) as amount
where invoice.invoice_id = iid;
$$
language sql
;
revoke execute on function update_invoice_collection_status(integer, integer, integer) from public;
grant execute on function update_invoice_collection_status(integer, integer, integer) to invoicer;
grant execute on function update_invoice_collection_status(integer, integer, integer) to admin;
commit;