Add expense_tax_amount to properly compute the net income
This commit is contained in:
parent
31eff5e3ab
commit
121f03b63c
|
@ -0,0 +1,24 @@
|
|||
-- Deploy numerus:expense_tax_amount to pg
|
||||
-- requires: schema_numerus
|
||||
-- requires: expense
|
||||
-- requires: expense_tax
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create or replace view expense_tax_amount
|
||||
as
|
||||
select expense_id
|
||||
, tax_id
|
||||
, sum(round(amount * tax_rate)::integer)::integer as amount
|
||||
from expense
|
||||
join expense_tax using (expense_id)
|
||||
group by expense_id
|
||||
, tax_id
|
||||
;
|
||||
|
||||
grant select on table expense_tax_amount to invoicer;
|
||||
grant select on table expense_tax_amount to admin;
|
||||
|
||||
commit;
|
|
@ -48,9 +48,9 @@ func ServeDashboard(w http.ResponseWriter, r *http.Request, _ httprouter.Params)
|
|||
select to_price(0, decimal_digits) as sales
|
||||
, to_price(coalesce(invoice.total, 0), decimal_digits) as income
|
||||
, to_price(coalesce(expense.total, 0), decimal_digits) as expenses
|
||||
, to_price(coalesce(tax.vat, 0), decimal_digits) as vat
|
||||
, to_price(coalesce(tax.irpf, 0), decimal_digits) as irpf
|
||||
, to_price(coalesce(invoice.total, 0) - coalesce(expense.total, 0) - coalesce(tax.vat, 0) + coalesce(tax.irpf, 0), decimal_digits) as net_income
|
||||
, to_price(coalesce(invoice_tax.vat, 0) - coalesce(expense_tax.vat, 0), decimal_digits) as vat
|
||||
, to_price(coalesce(invoice_tax.irpf, 0) + coalesce(expense_tax.irpf, 0), decimal_digits) as irpf
|
||||
, to_price(coalesce(invoice.total, 0) - coalesce(expense.total, 0) - (coalesce(invoice_tax.vat, 0) - coalesce(expense_tax.vat, 0)) + coalesce(expense_tax.irpf, 0), decimal_digits) as net_income
|
||||
from company
|
||||
left join (
|
||||
select company_id, sum(total)::integer as total
|
||||
|
@ -75,7 +75,18 @@ func ServeDashboard(w http.ResponseWriter, r *http.Request, _ httprouter.Params)
|
|||
join tax_class using (tax_class_id)
|
||||
where invoice_date between CURRENT_DATE - $2::interval and CURRENT_DATE - $3::interval
|
||||
group by invoice.company_id
|
||||
) as tax using (company_id)
|
||||
) as invoice_tax using (company_id)
|
||||
left join (
|
||||
select expense.company_id
|
||||
, sum(case when tax_class.name = 'IVA' then expense_tax_amount.amount else 0 end)::integer as vat
|
||||
, sum(case when tax_class.name = 'IRPF' then expense_tax_amount.amount else 0 end)::integer as irpf
|
||||
from expense
|
||||
join expense_tax_amount using (expense_id)
|
||||
join tax using (tax_id)
|
||||
join tax_class using (tax_class_id)
|
||||
where invoice_date between CURRENT_DATE - $2::interval and CURRENT_DATE - $3::interval
|
||||
group by expense.company_id
|
||||
) as expense_tax using (company_id)
|
||||
join currency using (currency_code)
|
||||
where company_id = $1
|
||||
`, company.Id, periodStart, periodEnd)
|
||||
|
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:expense_tax_amount from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop view if exists numerus.expense_tax_amount;
|
||||
|
||||
commit;
|
|
@ -76,3 +76,4 @@ add_expense [schema_numerus expense expense_tax tax company currency parse_price
|
|||
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
|
||||
expense_attachment [schema_numerus expense] 2023-05-13T19:11:21Z jordi fita mas <jordi@tandem.blog> # Add relation of expense attachments
|
||||
attach_to_expense [schema_numerus expense expense_attachment] 2023-05-15T10:18:31Z jordi fita mas <jordi@tandem.blog> # Add function to attach documents to expenses
|
||||
expense_tax_amount [schema_numerus expense expense_tax] 2023-05-18T10:15:40Z jordi fita mas <jordi@tandem.blog> # Add vier for expense tax amount
|
||||
|
|
|
@ -0,0 +1,97 @@
|
|||
-- Test expense_tax_amount
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(12);
|
||||
|
||||
set search_path to numerus, auth, public;
|
||||
|
||||
select has_view('expense_tax_amount');
|
||||
select table_privs_are('expense_tax_amount', 'guest', array[]::text[]);
|
||||
select table_privs_are('expense_tax_amount', 'invoicer', array['SELECT']);
|
||||
select table_privs_are('expense_tax_amount', 'admin', array['SELECT']);
|
||||
select table_privs_are('expense_tax_amount', 'authenticator', array[]::text[]);
|
||||
|
||||
select has_column('expense_tax_amount', 'expense_id');
|
||||
select col_type_is('expense_tax_amount', 'expense_id', 'integer');
|
||||
|
||||
select has_column('expense_tax_amount', 'tax_id');
|
||||
select col_type_is('expense_tax_amount', 'tax_id', 'integer');
|
||||
|
||||
select has_column('expense_tax_amount', 'amount');
|
||||
select col_type_is('expense_tax_amount', 'amount', 'integer');
|
||||
|
||||
|
||||
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 1', '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')
|
||||
;
|
||||
|
||||
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 (2, 1, 11, 'IRPF -15 %', -0.15)
|
||||
, (3, 1, 11, 'IVA 4 %', 0.04)
|
||||
, (4, 1, 11, 'IVA 10 %', 0.10)
|
||||
, (5, 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 (7, 1, 'Contact', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
|
||||
;
|
||||
|
||||
insert into expense (expense_id, company_id, invoice_number, invoice_date, contact_id, amount, currency_code)
|
||||
values ( 8, 1, 'I1', current_date, 7, 123, 'EUR')
|
||||
, ( 9, 1, 'I2', current_date, 7, 44444, 'EUR')
|
||||
, (10, 1, 'I3', current_date, 7, 9999, 'EUR')
|
||||
, (11, 1, 'I4', current_date, 7, 100000, 'EUR')
|
||||
;
|
||||
|
||||
insert into expense_tax (expense_id, tax_id, tax_rate)
|
||||
values ( 8, 2, -0.15)
|
||||
, ( 8, 5, 0.21)
|
||||
, ( 9, 3, 0.04)
|
||||
, (10, 4, 0.10)
|
||||
, (10, 5, 0.21)
|
||||
, (10, 2, -0.07)
|
||||
;
|
||||
|
||||
select bag_eq(
|
||||
$$ select expense_id, tax_id, amount from expense_tax_amount $$,
|
||||
$$ values ( 8, 2, -18)
|
||||
, ( 8, 5, 26)
|
||||
, ( 9, 3, 1778)
|
||||
, (10, 2, -700)
|
||||
, (10, 4, 1000)
|
||||
, (10, 5, 2100)
|
||||
$$,
|
||||
'Should compute the amount for all taxes in the expenses.'
|
||||
);
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
||||
|
|
@ -0,0 +1,11 @@
|
|||
-- Verify numerus:expense_tax_amount on pg
|
||||
|
||||
begin;
|
||||
|
||||
select expense_id
|
||||
, tax_id
|
||||
, amount
|
||||
from numerus.expense_tax_amount
|
||||
where false;
|
||||
|
||||
rollback;
|
Loading…
Reference in New Issue