Skip to content

Commit

Permalink
Fix SQL error in reconciliation
Browse files Browse the repository at this point in the history
When multiple payments have the same 'scn' (source) value *and* there's
at least one GL line with the same source value, the code wants to associate
that single line with both payments as a correction. That leads to an SQL error
('multiple rows returned in a query used as a value').

The solution is to exclude reconciliation lines where other lines with the
same 'scn' value exist, when considering GL lines a potential corrections.
  • Loading branch information
ehuelsmann committed Apr 29, 2022
1 parent df94ff5 commit e590503
Show file tree
Hide file tree
Showing 3 changed files with 63 additions and 1 deletion.
9 changes: 9 additions & 0 deletions sql/modules/Reconciliation.sql
Expand Up @@ -531,6 +531,15 @@ $$
and ac.transdate = rl.post_date
where la.entry_id = ac.entry_id
and rl.report_id = in_report_id
-- exclude 'scn' values associated with more than one
-- report line: the gl line can't be unambiguously
-- combined with a payment; hence it can't serve as
-- a correction...
and not exists (select 1 from cr_report_line rli
where rl.post_date = rli.post_date
and rl.report_id = rli.report_id
and rli.scn = rl.scn
and rl.id <> rli.id)
and not exists (select 1 from payment_links pl
where pl.entry_id = ac.entry_id))
where la.report_line_id is null
Expand Down
17 changes: 16 additions & 1 deletion xt/42-reconciliation.pg
Expand Up @@ -6,7 +6,7 @@ BEGIN;

-- Plan the tests.

SELECT plan(63);
SELECT plan(65);

-- Add data

Expand Down Expand Up @@ -274,6 +274,21 @@ BEGIN;
SELECT results_eq('test',ARRAY[-130.],'Cleared balance post-approval is 130');
DEALLOCATE test;


-- there are 3 items on account -11113, 2 are part of one payment each, the third is a GL transaction
-- all have the same 'source' value, which means that the GL entry will be considered a correction
-- to *both* payments. Because that's ambiguous, the GL item should be presented as a separate recon
-- line instead.
PREPARE test AS SELECT reconciliation__new_report_id(test_get_account_id('-11113'), 100, now()::date, false) > 0;
SELECT results_eq('test',ARRAY[true],'3 Create Recon Report');
DEALLOCATE test;

PREPARE test AS SELECT reconciliation__pending_transactions(currval('cr_report_id_seq')::int, 110) > 0;
SELECT results_eq('test',ARRAY[true],'3 Pending Transactions Ran');
DEALLOCATE test;



-- Finish the tests and clean up.
SELECT * FROM finish();

Expand Down
38 changes: 38 additions & 0 deletions xt/data/42-pg/Reconciliation.sql
Expand Up @@ -69,9 +69,11 @@ INSERT INTO ar (id, invnumber, amount_bc, netamount_bc, amount_tc, netamount_tc,
entity_credit_account, transdate, curr)
values (-209, '-2007', '10', '10', 10, 10, -201, '1000-01-03', 'XTS');


insert into payment (id, reference, payment_class, payment_date, entity_credit_id, currency)
values (-201, 'reference-test', 2, '1000-01-03', -201, 'XTS');


INSERT INTO gl (id, reference, transdate) values (-202, 'Recon gl test 1', '1000-01-01');
INSERT INTO gl (id, reference, transdate) values (-203, 'Recon gl test 2', '1000-01-01');
INSERT INTO gl (id, reference, transdate) values (-210, 'Recon gl test 3', '1000-01-03');
Expand Down Expand Up @@ -181,3 +183,39 @@ select -201, entry_id, 1
and chart_id = test_get_account_id('-11112')
and exists (select 1 from ar where ar.id = acc_trans.trans_id);

-- Test Act 3 - 2 payments and an adjustment, all with the same source

INSERT INTO account(id, accno, description, category, heading, contra)
values (-202, '-11113', 'Test Act 3', 'A',
(select id from account_heading WHERE accno = '000000000000000000000'), false);


INSERT INTO entity (id, control_code, name, entity_class, country_id)
values (-202, '-11113', 'Test 1', 1, 242);
INSERT INTO entity_credit_account (entity_id, id, meta_number, entity_class, ar_ap_account_id, curr)
values (-202, -202, 'T-11113', 1, -1000, 'XTS');


insert into payment (id, reference, payment_class, payment_date, entity_credit_id, currency)
values (-220, 'equal-reference', 2, '1000-01-01', -202, 'XTS');
insert into payment (id, reference, payment_class, payment_date, entity_credit_id, currency)
values (-221, 'equal-reference', 2, '1000-01-01', -202, 'XTS');


INSERT INTO gl (id, reference, transdate) values (-220, 'Recon adjustment test (act 3)', '1000-01-01');


INSERT INTO acc_trans (trans_id, chart_id, transdate, amount_bc, curr, amount_tc, source)
values (-200, test_get_account_id('-11113'), '1000-01-01', 10, 'XTS', 10, '1');
INSERT INTO payment_links (payment_id, entry_id, type)
values (-220, currval('acc_trans_entry_id_seq'), 1);

INSERT INTO acc_trans (trans_id, chart_id, transdate, amount_bc, curr, amount_tc, source)
values (-201, test_get_account_id('-11113'), '1000-01-01', 10, 'XTS', 10, '1');
INSERT INTO payment_links (payment_id, entry_id, type)
values (-221, currval('acc_trans_entry_id_seq'), 1);


INSERT INTO acc_trans (trans_id, chart_id, transdate, amount_bc, curr, amount_tc, source)
values (-220, test_get_account_id('-11113'), '1000-01-01', 10, 'XTS', 10, '1');

0 comments on commit e590503

Please sign in to comment.