Add SQL function to edit expenses
This commit is contained in:
parent
55d650bd62
commit
251080cbe5
|
@ -0,0 +1,50 @@
|
||||||
|
-- Deploy numerus:edit_expense to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
-- requires: expense
|
||||||
|
-- requires: currency
|
||||||
|
-- requires: parse_price
|
||||||
|
-- requires: tax
|
||||||
|
-- requires: tag_name
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create or replace function edit_expense(expense_slug uuid, invoice_date date, contact_id integer, invoice_number text, amount text, taxes integer[], tags tag_name[]) returns uuid as
|
||||||
|
$$
|
||||||
|
declare
|
||||||
|
eid integer;
|
||||||
|
begin
|
||||||
|
update expense
|
||||||
|
set invoice_date = edit_expense.invoice_date
|
||||||
|
, contact_id = edit_expense.contact_id
|
||||||
|
, invoice_number = edit_expense.invoice_number
|
||||||
|
, amount = parse_price(edit_expense.amount, decimal_digits)
|
||||||
|
, tags = edit_expense.tags
|
||||||
|
from currency
|
||||||
|
where slug = expense_slug
|
||||||
|
and currency.currency_code = expense.currency_code
|
||||||
|
returning expense_id
|
||||||
|
into eid;
|
||||||
|
|
||||||
|
if eid is null then
|
||||||
|
return null;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
delete from expense_tax where expense_id = eid;
|
||||||
|
|
||||||
|
insert into expense_tax (expense_id, tax_id, tax_rate)
|
||||||
|
select eid, tax_id, tax.rate
|
||||||
|
from tax
|
||||||
|
join unnest(taxes) as etax(tax_id) using (tax_id);
|
||||||
|
|
||||||
|
return expense_slug;
|
||||||
|
end;
|
||||||
|
$$
|
||||||
|
language plpgsql;
|
||||||
|
|
||||||
|
revoke execute on function edit_expense(uuid, date, integer, text, text, integer[], tag_name[]) from public;
|
||||||
|
grant execute on function edit_expense(uuid, date, integer, text, text, integer[], tag_name[]) to invoicer;
|
||||||
|
grant execute on function edit_expense(uuid, date, integer, text, text, integer[], tag_name[]) to admin;
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:edit_expense from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.edit_expense(uuid, date, integer, text, text, integer[], numerus.tag_name[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -73,3 +73,4 @@ edit_contact [schema_numerus email extension_uri country_code tag_name contact e
|
||||||
expense [schema_numerus contact company currency_code currency tag_name] 2023-04-30T13:46:36Z jordi fita mas <jordi@tandem.blog> # Add the expense relation
|
expense [schema_numerus contact company currency_code currency tag_name] 2023-04-30T13:46:36Z jordi fita mas <jordi@tandem.blog> # Add the expense relation
|
||||||
expense_tax [schema_numerus expense tax tax_rate] 2023-05-01T14:08:33Z jordi fita mas <jordi@tandem.blog> # Add relation of expense taxes
|
expense_tax [schema_numerus expense tax tax_rate] 2023-05-01T14:08:33Z jordi fita mas <jordi@tandem.blog> # Add relation of expense taxes
|
||||||
add_expense [schema_numerus expense expense_tax tax company currency parse_price tag_name] 2023-05-02T08:00:26Z jordi fita mas <jordi@tandem.blog> # Add function to create new expenses
|
add_expense [schema_numerus expense expense_tax tax company currency parse_price tag_name] 2023-05-02T08:00:26Z jordi fita mas <jordi@tandem.blog> # Add function to create new expenses
|
||||||
|
edit_expense [schema_numerus expense currency parse_price tax tag_name] 2023-05-04T09:53:04Z jordi fita mas <jordi@tandem.blog> # Add function to edit expenses
|
||||||
|
|
|
@ -0,0 +1,103 @@
|
||||||
|
-- Test edit_expense
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(13);
|
||||||
|
|
||||||
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
select has_function('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]']);
|
||||||
|
select function_lang_is('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'plpgsql');
|
||||||
|
select function_returns('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'uuid');
|
||||||
|
select isnt_definer('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]']);
|
||||||
|
select volatility_is('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'volatile');
|
||||||
|
select function_privs_are('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'guest', array []::text[]);
|
||||||
|
select function_privs_are('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'edit_expense', array ['uuid', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'authenticator', array []::text[]);
|
||||||
|
|
||||||
|
|
||||||
|
set client_min_messages to warning;
|
||||||
|
truncate expense_tax cascade;
|
||||||
|
truncate expense cascade;
|
||||||
|
truncate contact cascade;
|
||||||
|
truncate tax cascade;
|
||||||
|
truncate tax_class cascade;
|
||||||
|
truncate payment_method cascade;
|
||||||
|
truncate company cascade;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
|
||||||
|
set constraints "company_default_payment_method_id_fkey" deferred;
|
||||||
|
|
||||||
|
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
|
||||||
|
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 111)
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into payment_method (payment_method_id, company_id, name, instructions)
|
||||||
|
values (111, 1, 'cash', 'cash')
|
||||||
|
, (112, 1, 'bank', 'send money to my bank account')
|
||||||
|
;
|
||||||
|
|
||||||
|
set constraints "company_default_payment_method_id_fkey" immediate;
|
||||||
|
|
||||||
|
insert into tax_class (tax_class_id, company_id, name)
|
||||||
|
values (11, 1, 'tax')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into tax (tax_id, company_id, tax_class_id, name, rate)
|
||||||
|
values (3, 1, 11, 'IRPF -15 %', -0.15)
|
||||||
|
, (4, 1, 11, 'IVA 21 %', 0.21)
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
|
||||||
|
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
||||||
|
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into expense (expense_id, company_id, slug, invoice_number, invoice_date, contact_id, amount, currency_code, tags)
|
||||||
|
values (15, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'INV1', '2023-05-04', 12, 111, 'EUR', '{tag1}')
|
||||||
|
, (16, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'INV2', '2023-05-05', 13, 222, 'EUR', '{tag2}')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into expense_tax (expense_id, tax_id, tax_rate)
|
||||||
|
values (15, 4, 0.21)
|
||||||
|
, (15, 3, -0.07)
|
||||||
|
, (16, 4, 0.20)
|
||||||
|
;
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select edit_expense('7ac3ae0e-b0c1-4206-a19b-0be20835edd4', '2023-05-06', 13, 'INV11', '1.12', '{4}', array['tag1']) $$,
|
||||||
|
'Should be able to edit the first expense'
|
||||||
|
);
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select edit_expense('b57b980b-247b-4be4-a0b7-03a7819c53ae', '2023-05-07', 12, 'INV22', '3.33', '{4,3}', array['tag1', 'tag3']) $$,
|
||||||
|
'Should be able to edit the second expense'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select invoice_number, invoice_date, contact_id, amount, tags from expense $$,
|
||||||
|
$$ values ('INV11', '2023-05-06'::date, 13, 112, '{tag1}'::tag_name[])
|
||||||
|
, ('INV22', '2023-05-07'::date, 12, 333, '{tag1,tag3}'::tag_name[])
|
||||||
|
$$,
|
||||||
|
'Should have updated all expenses'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select invoice_number, tax_id, tax_rate from expense_tax join expense using (expense_id) $$,
|
||||||
|
$$ values ('INV11', 4, 0.21)
|
||||||
|
, ('INV22', 3, -0.15)
|
||||||
|
, ('INV22', 4, 0.21)
|
||||||
|
$$,
|
||||||
|
'Should have updated all expense taxes, added new ones, and removed the ones not given to the function'
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:edit_expense on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.edit_expense(uuid, date, integer, text, text, integer[], numerus.tag_name[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
Loading…
Reference in New Issue