-- Deploy numerus:compute_new_expense_amount to pg -- requires: schema_numerus -- requires: roles -- requires: company -- requires: tax -- requires: new_expense_amount begin; set search_path to numerus, public; create or replace function compute_new_expense_amount(company_id integer, subtotal text, taxes integer[]) returns new_expense_amount as $$ declare result new_expense_amount; begin if trim(subtotal) = '' then subtotal = '0'; end if; if array_length(taxes, 1) > 0 then with line as ( select round(parse_price(subtotal, currency.decimal_digits)) as price , tax_id , decimal_digits from unnest (taxes) as tax(tax_id) join company on company.company_id = compute_new_expense_amount.company_id join currency using (currency_code) ) , tax_amount as ( select tax_id , sum(round(price * tax.rate)::integer)::integer as amount , decimal_digits from line join tax using (tax_id) group by tax_id, decimal_digits ) , tax_total as ( select sum(amount)::integer as amount , array_agg(array[name, to_price(amount, decimal_digits)]) as taxes from tax_amount join tax using (tax_id) ) select coalesce(tax_total.taxes, array[]::text[][]) , to_price(price::integer + coalesce(tax_total.amount, 0), decimal_digits) as total from line, tax_total into result.taxes, result.total; else select array[]::text[][] , to_price(coalesce(parse_price(subtotal, decimal_digits), 0), decimal_digits) from company join currency using (currency_code) where company.company_id = compute_new_expense_amount.company_id into result.taxes, result.total ; end if; return result; end; $$ language plpgsql stable ; revoke execute on function compute_new_expense_amount(integer, text, integer[]) from public; grant execute on function compute_new_expense_amount(integer, text, integer[]) to invoicer; grant execute on function compute_new_expense_amount(integer, text, integer[]) to admin; commit;