Add function to create expenses
This commit is contained in:
parent
b904aea9f2
commit
5984745c89
|
@ -0,0 +1,50 @@
|
||||||
|
-- Deploy numerus:add_expense to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
-- requires: expense
|
||||||
|
-- requires: expense_tax
|
||||||
|
-- requires: tax
|
||||||
|
-- requires: company
|
||||||
|
-- requires: currency
|
||||||
|
-- requires: parse_price
|
||||||
|
-- requires: tax
|
||||||
|
-- requires: tag_name
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create or replace function add_expense(company integer, invoice_date date, contact_id integer, invoice_number text, amount text, taxes integer[], tags tag_name[]) returns uuid as
|
||||||
|
$$
|
||||||
|
declare
|
||||||
|
eid integer;
|
||||||
|
eslug uuid;
|
||||||
|
begin
|
||||||
|
insert into expense (company_id, contact_id, invoice_number, invoice_date, amount, currency_code, tags)
|
||||||
|
select company_id
|
||||||
|
, contact_id
|
||||||
|
, invoice_number
|
||||||
|
, invoice_date
|
||||||
|
, parse_price(amount, currency.decimal_digits)
|
||||||
|
, currency_code
|
||||||
|
, tags
|
||||||
|
from company
|
||||||
|
join currency using (currency_code)
|
||||||
|
where company.company_id = add_expense.company
|
||||||
|
returning expense_id, slug
|
||||||
|
into eid, eslug;
|
||||||
|
|
||||||
|
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 eslug;
|
||||||
|
end;
|
||||||
|
$$
|
||||||
|
language plpgsql;
|
||||||
|
|
||||||
|
revoke execute on function add_expense(integer, date, integer, text, text, integer[], tag_name[]) from public;
|
||||||
|
grant execute on function add_expense(integer, date, integer, text, text, integer[], tag_name[]) to invoicer;
|
||||||
|
grant execute on function add_expense(integer, date, integer, text, text, integer[], tag_name[]) to admin;
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:add_expense from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.add_expense(integer, date, integer, text, text, integer[], numerus.tag_name[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -72,3 +72,4 @@ add_contact [schema_numerus extension_vat email extension_pg_libphonenumber exte
|
||||||
edit_contact [schema_numerus email extension_uri country_code tag_name contact extension_vat extension_pg_libphonenumber] 2023-03-25T23:20:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
|
edit_contact [schema_numerus email extension_uri country_code tag_name contact extension_vat extension_pg_libphonenumber] 2023-03-25T23:20:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
|
||||||
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
|
||||||
|
|
|
@ -0,0 +1,102 @@
|
||||||
|
-- Test add_expense
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(14);
|
||||||
|
|
||||||
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
select has_function('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]']);
|
||||||
|
select function_lang_is('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'plpgsql');
|
||||||
|
select function_returns('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'uuid');
|
||||||
|
select isnt_definer('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]']);
|
||||||
|
select volatility_is('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'volatile');
|
||||||
|
select function_privs_are('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'guest', array []::text[]);
|
||||||
|
select function_privs_are('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'invoicer', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'admin', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'add_expense', array ['integer', 'date', 'integer', 'text', 'text', 'integer[]', 'tag_name[]'], 'authenticator', array []::text[]);
|
||||||
|
|
||||||
|
|
||||||
|
set client_min_messages to warning;
|
||||||
|
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, invoice_number_format, default_payment_method_id)
|
||||||
|
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', '"F"YYYY0000', 111)
|
||||||
|
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', '"INV"000-YY', 222)
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into payment_method (payment_method_id, company_id, name, instructions)
|
||||||
|
values (111, 1, 'cash', 'cash')
|
||||||
|
, (222, 2, 'cash', 'cash')
|
||||||
|
;
|
||||||
|
|
||||||
|
set constraints "company_default_payment_method_id_fkey" immediate;
|
||||||
|
|
||||||
|
insert into tax_class (tax_class_id, company_id, name)
|
||||||
|
values (11, 1, 'tax')
|
||||||
|
, (22, 2, '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)
|
||||||
|
, (5, 2, 22, 'IRPF -7 %', -0.07)
|
||||||
|
, (6, 2, 22, 'IVA 10 %', 0.10)
|
||||||
|
;
|
||||||
|
|
||||||
|
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')
|
||||||
|
, (14, 2, 'Contact 4.1', 'XX777', '', '999-999-999', 'e@e', '', '', '', '', '', 'ES')
|
||||||
|
, (15, 2, 'Contact 4.2', 'XX888', '', '000-000-000', 'f@f', '', '', '', '', '', 'ES')
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_expense(1, '2023-05-02', 12, 'Invoice 1', '11.11', '{4}', '{tag1,tag2}') $$,
|
||||||
|
'Should be able to insert an expense for the first company with a tax'
|
||||||
|
);
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_expense(1, '2023-05-03', 13, 'Invoice 2', '22.22', '{4,3}', '{}') $$,
|
||||||
|
'Should be able to insert a second expense for the first company with two taxes'
|
||||||
|
);
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_expense(2, '2023-05-04', 15, 'Invoice 3', '33.33', '{}', '{tag3}') $$,
|
||||||
|
'Should be able to insert an invoice for the second company with no tax'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select company_id, invoice_number, invoice_date, contact_id, amount, currency_code, tags, created_at from expense $$,
|
||||||
|
$$ values (1, 'Invoice 1', '2023-05-02'::date, 12, 1111, 'EUR', '{tag1,tag2}'::tag_name[], current_timestamp)
|
||||||
|
, (1, 'Invoice 2', '2023-05-03'::date, 13, 2222, 'EUR', '{}'::tag_name[], current_timestamp)
|
||||||
|
, (2, 'Invoice 3', '2023-05-04'::date, 15, 3333, 'USD', '{tag3}'::tag_name[], current_timestamp)
|
||||||
|
$$,
|
||||||
|
'Should have created all expenses'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select invoice_number, tax_id, tax_rate from expense_tax join expense using (expense_id) $$,
|
||||||
|
$$ values ('Invoice 1', 4, 0.21)
|
||||||
|
, ('Invoice 2', 4, 0.21)
|
||||||
|
, ('Invoice 2', 3, -0.15)
|
||||||
|
$$,
|
||||||
|
'Should have created all invoice product taxes'
|
||||||
|
);
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:add_expense on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.add_expense(integer, date, integer, text, text, integer[], numerus.tag_name[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
Loading…
Reference in New Issue