-- Deploy numerus:update_expense_payment_status to pg -- requires: roles -- requires: schema_numerus -- requires: expense -- requires: payment -- requires: expense_payment -- requires: available_expense_status -- requires: available_payment_status begin; set search_path to numerus, public; create or replace function update_expense_payment_status(pid integer, eid integer, amount_cents integer) returns void as $$ update payment set payment_status = case when expense.amount > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end from expense where expense.expense_id = eid and payment_id = pid ; update expense set expense_status = case when paid_amount >= expense.amount then 'paid' else 'partial' end from ( select expense_payment.expense_id , sum(payment.amount) as paid_amount from expense_payment join payment using (payment_id) group by expense_payment.expense_id ) as payment where payment.expense_id = expense.expense_id and expense.expense_id = eid ; $$ language sql ; revoke execute on function update_expense_payment_status(integer, integer, integer) from public; grant execute on function update_expense_payment_status(integer, integer, integer) to invoicer; grant execute on function update_expense_payment_status(integer, integer, integer) to admin; commit;