This is to handle refunds, which are invoices with negative amounts, that can be both issued or received (i.e., an “expense”). The API provided by PostgreSQL is mostly the same, and internally it deals with negatives, so the Go package only had to change selects of collection.
54 lines
1.4 KiB
PL/PgSQL
54 lines
1.4 KiB
PL/PgSQL
-- Deploy numerus:edit_payment to pg
|
|
-- requires: roles
|
|
-- requires: schema_numerus
|
|
-- requires: payment
|
|
-- requires: expense_payment
|
|
-- requires: currency
|
|
-- requires: parse_price
|
|
-- requires: tag_name
|
|
-- requires: update_expense_payment_status
|
|
|
|
begin;
|
|
|
|
set search_path to numerus, public;
|
|
|
|
create or replace function edit_payment(payment_slug uuid, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as
|
|
$$
|
|
declare
|
|
pid integer;
|
|
eid integer;
|
|
amount_cents integer;
|
|
begin
|
|
update payment
|
|
set payment_date = edit_payment.payment_date
|
|
, payment_account_id = edit_payment.payment_account_id
|
|
, description = edit_payment.description
|
|
, amount = -parse_price(edit_payment.amount, decimal_digits)
|
|
, tags = edit_payment.tags
|
|
from currency
|
|
where slug = payment_slug
|
|
and currency.currency_code = payment.currency_code
|
|
returning payment_id, payment.amount
|
|
into pid, amount_cents
|
|
;
|
|
|
|
select expense_id into eid
|
|
from expense_payment
|
|
where payment_id = pid;
|
|
|
|
if eid is not null then
|
|
perform update_expense_payment_status(pid, eid, amount_cents);
|
|
end if;
|
|
|
|
return payment_slug;
|
|
end
|
|
$$
|
|
language plpgsql
|
|
;
|
|
|
|
revoke execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) from public;
|
|
grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to invoicer;
|
|
grant execute on function edit_payment(uuid, date, integer, text, text, tag_name[]) to admin;
|
|
|
|
commit;
|