-- Deploy numerus:add_payment to pg
-- requires: roles
-- requires: schema_numerus
-- requires: payment
-- requires: expense_payment
-- requires: company
-- requires: currency
-- requires: parse_price
-- requires: tag_name
-- requires: update_expense_payment_status

begin;

set search_path to numerus, public;

create or replace function add_payment(company integer, expense_id integer, payment_date date, payment_account_id integer, description text, amount text, tags tag_name[]) returns uuid as
$$
declare
	pslug uuid;
	pid integer;
	amount_cents integer;
begin
	insert into payment
	( company_id
	, payment_account_id
	, description
	, payment_date
	, amount
	, currency_code
	, payment_status
	, tags
	)
	select company_id
	     , payment_account_id
	     , description
	     , payment_date
	     , parse_price(amount, currency.decimal_digits)
	     , currency_code
	     , 'complete'
	     , tags
	from company
	join currency using (currency_code)
	where company.company_id = add_payment.company
	returning payment_id, slug, payment.amount
	into pid, pslug, amount_cents
	;

	if expense_id is not null then
		-- must be inserted before updating statuses, so that it can see this
		-- payment’s amount too.
		insert into expense_payment (expense_id, payment_id)
		values (expense_id, pid);

		perform update_expense_payment_status(pid, expense_id, amount_cents);
	end if;

	return pslug;
end
$$
	language plpgsql
;

revoke execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) from public;
grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to invoicer;
grant execute on function add_payment(integer, integer, date, integer, text, text, tag_name[]) to admin;

commit;