From 9ab08deaa17e3315ffdd9b36867be8695a56cdef Mon Sep 17 00:00:00 2001 From: jordi fita mas Date: Thu, 15 Aug 2024 03:51:30 +0200 Subject: [PATCH] Include the taxes when updating an expense to paid or partial --- deploy/update_expense_payment_status.sql | 13 ++++-- sqitch.plan | 2 +- test/add_payment.sql | 49 +++++++++++++++++++++- test/edit_payment.sql | 52 +++++++++++++++++++++++- 4 files changed, 110 insertions(+), 6 deletions(-) diff --git a/deploy/update_expense_payment_status.sql b/deploy/update_expense_payment_status.sql index b1fb9bf..d73a892 100644 --- a/deploy/update_expense_payment_status.sql +++ b/deploy/update_expense_payment_status.sql @@ -4,6 +4,7 @@ -- requires: expense -- requires: payment -- requires: expense_payment +-- requires: expense_tax_amount -- requires: available_expense_status -- requires: available_payment_status @@ -14,15 +15,16 @@ set search_path to numerus, public; create or replace function update_expense_payment_status(pid integer, eid integer, amount_cents integer) returns void as $$ update payment - set payment_status = case when expense.amount > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end + set payment_status = case when expense.amount + coalesce(tax.amount, 0) > amount_cents or exists (select 1 from expense_payment as ep where ep.expense_id = expense.expense_id and payment_id <> pid) then 'partial' else 'complete' end from expense + left join ( select expense_id, sum(amount) as amount from expense_tax_amount group by expense_id) as tax using (expense_id) where expense.expense_id = eid and payment_id = pid ; update expense set expense_status = case - when paid_amount >= expense.amount then 'paid' + when paid_amount >= expense.amount + tax_amount then 'paid' when paid_amount = 0 then 'pending' else 'partial' end from ( @@ -30,7 +32,12 @@ $$ from expense_payment join payment using (payment_id) where expense_payment.expense_id = eid - ) as payment + ) as payment, + ( + select coalesce (sum(amount), 0) as tax_amount + from expense_tax_amount + where expense_id = eid + ) as tax where expense.expense_id = eid ; $$ diff --git a/sqitch.plan b/sqitch.plan index 782e9b7..f948eb3 100644 --- a/sqitch.plan +++ b/sqitch.plan @@ -149,7 +149,7 @@ available_payment_status [schema_numerus payment_status payment_status_i18n] 202 payment [roles schema_numerus company payment_account currency tag_name payment_status extension_pgcrypto] 2024-08-01T01:28:59Z jordi fita mas # Add relation for accounts payable expense_payment [roles schema_numerus expense payment] 2024-08-04T03:44:30Z jordi fita mas # Add relation of expense payments available_expense_status [available_expense_status@v2] 2024-08-04T05:24:08Z jordi fita mas # Add “partial” expense status -update_expense_payment_status [roles schema_numerus expense payment expense_payment available_expense_status available_payment_status] 2024-08-04T06:36:00Z jordi fita mas # Add function to update payment and expense status +update_expense_payment_status [roles schema_numerus expense payment expense_payment expense_tax_amount available_expense_status available_payment_status] 2024-08-04T06:36:00Z jordi fita mas # Add function to update payment and expense status add_payment [roles schema_numerus payment expense_payment company currency parse_price tag_name update_expense_payment_status] 2024-08-04T03:16:55Z jordi fita mas # Add function to insert new payments edit_payment [roles schema_numerus payment expense_payment currency parse_price tag_name update_expense_payment_status] 2024-08-04T03:31:45Z jordi fita mas # Add function to update payments payment_attachment [roles schema_numerus payment] 2024-08-11T21:01:50Z jordi fita mas # Add relation of payment attachments diff --git a/test/add_payment.sql b/test/add_payment.sql index 6575b5a..5542389 100644 --- a/test/add_payment.sql +++ b/test/add_payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(17); +select plan(20); set search_path to numerus, auth, public; @@ -25,8 +25,11 @@ set client_min_messages to warning; truncate expense_payment cascade; truncate payment cascade; truncate payment_account cascade; +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; @@ -45,6 +48,16 @@ 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) +; + insert into contact (contact_id, company_id, name) values ( 9, 1, 'Customer 1') , (10, 2, 'Customer 2') @@ -55,6 +68,16 @@ values (12, 1, 'REF123', 9, '2011-01-11', 111, 'EUR') , (13, 2, 'INV001', 10, '2011-01-11', 111, 'USD') , (14, 2, 'INV002', 10, '2022-02-22', 222, 'USD') , (15, 2, 'INV003', 10, '2022-02-22', 222, 'USD') + , (16, 1, 'REF001', 9, '2023-03-03', 10000, 'EUR') + , (17, 1, 'REF002', 9, '2023-03-03', 10000, 'EUR') + , (18, 1, 'REF003', 9, '2023-03-03', 10000, 'EUR') +; + +insert into expense_tax (expense_id, tax_id, tax_rate) +values (16, 3, 0.04) + , (17, 2, -0.15) + , (18, 2, -0.15) + , (18, 4, 0.10) ; insert into payment_account (payment_account_id, company_id, payment_account_type, name) @@ -87,6 +110,21 @@ select lives_ok( 'Should be able to insert a partial payment for the third expense' ); +select lives_ok( + $$ select add_payment(1, 16, '2023-03-06', 11, 'Re: REF001', '103.99', array[]::tag_name[]) $$, + 'Should be able to pay an expense with taxes' +); + +select lives_ok( + $$ select add_payment(1, 17, '2023-03-06', 11, 'Re: REF002', '85', array[]::tag_name[]) $$, + 'Should be able to pay an expense with negative taxes' +); + +select lives_ok( + $$ select add_payment(1, 18, '2023-03-06', 11, 'Re: REF003', '95', array[]::tag_name[]) $$, + 'Should be able to pay an expense with multiple taxes' +); + select bag_eq( $$ select company_id, description, payment_date::text, payment_account_id, amount, currency_code, payment_status, tags::text, created_at from payment $$, $$ values (1, '“Protection”', '2023-05-02', 11, 1111, 'EUR', 'complete', '{tag1,tag2}', current_timestamp) @@ -94,6 +132,9 @@ select bag_eq( , (2, 'First payment of INV002', '2023-05-04', 22, 100, 'USD', 'partial', '{}', current_timestamp) , (2, 'Second payment of INV002', '2023-05-05', 22, 122, 'USD', 'partial', '{}', current_timestamp) , (2, 'Partial payment of INV003', '2023-05-06', 22, 111, 'USD', 'partial', '{}', current_timestamp) + , (1, 'Re: REF001', '2023-03-06', 11, 10399, 'EUR', 'partial', '{}', current_timestamp) + , (1, 'Re: REF002', '2023-03-06', 11, 8500, 'EUR', 'complete', '{}', current_timestamp) + , (1, 'Re: REF003', '2023-03-06', 11, 9500, 'EUR', 'complete', '{}', current_timestamp) $$, 'Should have created all payments' ); @@ -104,6 +145,9 @@ select bag_eq( , (14, 'First payment of INV002') , (14, 'Second payment of INV002') , (15, 'Partial payment of INV003') + , (16, 'Re: REF001') + , (17, 'Re: REF002') + , (18, 'Re: REF003') $$, 'Should have linked all expenses to payments' ); @@ -114,6 +158,9 @@ select bag_eq( , (13, 'paid') , (14, 'paid') , (15, 'partial') + , (16, 'partial') + , (17, 'paid') + , (18, 'paid') $$, 'Should have updated the status of expenses' ); diff --git a/test/edit_payment.sql b/test/edit_payment.sql index a7d6835..bd2029c 100644 --- a/test/edit_payment.sql +++ b/test/edit_payment.sql @@ -5,7 +5,7 @@ reset client_min_messages; begin; -select plan(14); +select plan(17); set search_path to numerus, public; @@ -24,8 +24,11 @@ select function_privs_are('numerus', 'edit_payment', array ['uuid', 'date', 'int set client_min_messages to warning; truncate expense_payment cascade; truncate payment cascade; +truncate expense_tax cascade; truncate expense cascade; truncate contact cascade; +truncate tax cascade; +truncate tax_class cascade; truncate payment_account cascade; truncate payment_method cascade; truncate company cascade; @@ -44,6 +47,16 @@ 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) +; + insert into contact (contact_id, company_id, name) values ( 9, 1, 'Customer 1') ; @@ -52,6 +65,16 @@ insert into expense (expense_id, company_id, invoice_number, contact_id, invoice values (13, 1, 'INV001', 9, '2011-01-11', 111, 'EUR', 'paid') , (14, 1, 'INV002', 9, '2022-02-22', 222, 'EUR', 'paid') , (15, 1, 'INV003', 9, '2022-02-22', 333, 'EUR', 'partial') + , (16, 1, 'REF001', 9, '2023-03-03', 10000, 'EUR', 'paid') + , (17, 1, 'REF002', 9, '2023-03-03', 10000, 'EUR', 'paid') + , (18, 1, 'REF003', 9, '2023-03-03', 10000, 'EUR', 'paid') +; + +insert into expense_tax (expense_id, tax_id, tax_rate) +values (16, 3, 0.04) + , (17, 2, -0.15) + , (18, 2, -0.15) + , (18, 4, 0.10) ; insert into payment_account (payment_account_id, company_id, payment_account_type, name) @@ -65,6 +88,9 @@ values (16, 1, '7ac3ae0e-b0c1-4206-a19b-0be20835edd4', 'Payment INV001', '2023-0 , (17, 1, 'b57b980b-247b-4be4-a0b7-03a7819c53ae', 'First INV002', '2023-05-05', 13, 100, 'EUR', 'partial', '{tag2}') , (18, 1, '3bdad7a8-4a1e-4ae0-b5c6-015e51ee0502', 'Second INV002', '2023-05-06', 13, 122, 'EUR', 'partial', '{tag1,tag3}') , (19, 1, '5a524bee-8311-4d13-9adf-ef6310b26990', 'Partial INV003', '2023-05-07', 11, 123, 'EUR', 'partial', '{}') + , (20, 1, '65222c3b-4faa-4be4-b39c-5bd170a943cf', 'Re: REF001', '2023-03-07', 11, 10400, 'EUR', 'complete', '{}') + , (21, 1, 'dbb699cf-d1f4-40ff-96cb-8f29e238d51d', 'Re: REF002', '2023-03-07', 11, 8500, 'EUR', 'complete', '{}') + , (22, 1, '0756a50f-2957-4661-abd2-e422a848af4e', 'Re: REF003', '2023-03-07', 11, 9500, 'EUR', 'complete', '{}') ; insert into expense_payment (expense_id, payment_id) @@ -72,6 +98,9 @@ values (13, 16) , (14, 17) , (14, 18) , (15, 19) + , (16, 20) + , (17, 21) + , (18, 22) ; select lives_ok( @@ -89,12 +118,30 @@ select lives_ok( 'Should be able to complete a previously partial payment' ); +select lives_ok( + $$ select edit_payment('65222c3b-4faa-4be4-b39c-5bd170a943cf', '2023-03-10', 11, 'Re: REF001', '103.99', array[]::tag_name[]) $$, + 'Should be able to make partial a payment with tax.' +); + +select lives_ok( + $$ select edit_payment('dbb699cf-d1f4-40ff-96cb-8f29e238d51d', '2023-03-10', 11, 'Re: REF002', '84.99', array[]::tag_name[]) $$, + 'Should be able to make partial a payment with negative tax.' +); + +select lives_ok( + $$ select edit_payment('0756a50f-2957-4661-abd2-e422a848af4e', '2023-03-10', 11, 'Re: REF003', '94.99', array[]::tag_name[]) $$, + 'Should be able to make partial a payment with multiple taxe.' +); + select bag_eq( $$ select description, payment_date::text, payment_account_id, amount, payment_status, tags::text from payment $$, $$ values ('Partial INV001', '2023-05-06', 13, 100, 'partial', '{tag1}') , ('First INV002', '2023-05-07', 12, 50, 'partial', '{tag1,tag3}') , ('Second INV002', '2023-05-06', 13, 122, 'partial', '{tag1,tag3}') , ('Complete INV003', '2023-05-01', 11, 333, 'complete', '{}') + , ('Re: REF001', '2023-03-10', 11, 10399, 'partial', '{}') + , ('Re: REF002', '2023-03-10', 11, 8499, 'partial', '{}') + , ('Re: REF003', '2023-03-10', 11, 9499, 'partial', '{}') $$, 'Should have updated all payments' ); @@ -104,6 +151,9 @@ select bag_eq( $$ values (13, 'partial') , (14, 'partial') , (15, 'paid') + , (16, 'partial') + , (17, 'partial') + , (18, 'partial') $$, 'Should have updated expenses too' );