50 lines
1.6 KiB
PL/PgSQL
50 lines
1.6 KiB
PL/PgSQL
-- Deploy numerus:update_invoice_collection_status to pg
|
|
-- requires: roles
|
|
-- requires: schema_numerus
|
|
-- requires: invoice
|
|
-- requires: collection
|
|
-- requires: invoice_collection
|
|
-- 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 collection
|
|
set payment_status = case when invoice_amount.total > amount_cents or exists (select 1 from invoice_collection as ic where ic.collection_id = invoice_amount.invoice_id and collection_id <> cid) then 'partial' else 'complete' end
|
|
from invoice_amount
|
|
where invoice_id = iid
|
|
and collection_id = cid
|
|
;
|
|
|
|
update invoice
|
|
set invoice_status = case
|
|
when collected_amount >= total_amount then 'paid'
|
|
when collected_amount = 0 then 'created'
|
|
else 'partial' end
|
|
from (
|
|
select coalesce(sum(collection.amount), 0) as collected_amount
|
|
from invoice_collection
|
|
join collection using (collection_id)
|
|
where invoice_collection.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;
|