Skip to content

Commit

Permalink
fix(Trial Balance): limit lookup to FY
Browse files Browse the repository at this point in the history
This commit limits the Trial Balance lookup to only oldest fiscal year.
It also fixes a grouping bug that summed the before total an extra time.
This lead to N * beginning_balance being reported for N transactions.

Closes Third-Culture-Software#2568.
  • Loading branch information
jniles committed Feb 27, 2018
1 parent 7b6be38 commit 227097a
Show file tree
Hide file tree
Showing 3 changed files with 19 additions and 6 deletions.
19 changes: 16 additions & 3 deletions server/models/procedures/trial_balance.sql
Original file line number Diff line number Diff line change
Expand Up @@ -190,23 +190,36 @@ CREATE PROCEDURE TrialBalanceSummary()
BEGIN
-- this assumes lines have been staged using CALL StageTrialBalanceTransaction()

-- fiscal year to limit period_total search
DECLARE fiscalYearId MEDIUMINT;

-- get the fiscal year of the oldest record to limit period_total search
SET fiscalYearId = (
SELECT MIN(fiscal_year_id)
FROM posting_journal JOIN stage_trial_balance_transaction
ON posting_journal.record_uuid = stage_trial_balance_transaction.record_uuid
);

-- gather the staged accounts
CREATE TEMPORARY TABLE IF NOT EXISTS staged_accounts AS
SELECT DISTINCT account_id FROM posting_journal JOIN stage_trial_balance_transaction
ON posting_journal.record_uuid = stage_trial_balance_transaction.record_uuid;

-- gather the beginning period_totals
CREATE TEMPORARY TABLE before_totals AS
SELECT u.account_id, IFNULL(SUM(debit - credit), 0) AS balance_before
SELECT u.account_id, IFNULL(SUM(totals.debit - totals.credit), 0) AS balance_before
FROM staged_accounts as u
LEFT JOIN period_total ON u.account_id = period_total.account_id
LEFT JOIN (
SELECT account_id, debit, credit FROM period_total
WHERE period_total.fiscal_year_id = fiscalYearId
) totals ON u.account_id = totals.account_id
GROUP BY u.account_id;

SELECT account_id, account.number AS number, account.label AS label,
balance_before, debit_equiv, credit_equiv,
balance_before + debit_equiv - credit_equiv AS balance_final
FROM (
SELECT posting_journal.account_id, SUM(totals.balance_before) AS balance_before, SUM(debit_equiv) AS debit_equiv,
SELECT posting_journal.account_id, MAX(totals.balance_before) AS balance_before, SUM(debit_equiv) AS debit_equiv,
SUM(credit_equiv) AS credit_equiv
FROM posting_journal JOIN before_totals as totals
ON posting_journal.account_id = totals.account_id
Expand Down
4 changes: 2 additions & 2 deletions server/models/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -176,7 +176,7 @@ CREATE TABLE `rubric_payroll` (
`is_discount` tinyint(1) DEFAULT 0,
`is_tax` tinyint(1) DEFAULT 0,
`is_social_care` tinyint(1) DEFAULT 0,
`is_membership_fee` tinyint(1) DEFAULT 0,
`is_membership_fee` tinyint(1) DEFAULT 0,
`debtor_account_id` int(10) unsigned DEFAULT NULL,
`expense_account_id` int(10) unsigned DEFAULT NULL,
`is_ipr` tinyint(1) DEFAULT 0,
Expand Down Expand Up @@ -1587,7 +1587,7 @@ CREATE TABLE `taxe_ipr` (
`currency_id` TINYINT(3) UNSIGNED NOT NULL,
PRIMARY KEY (`id`),
KEY `currency_id` (`currency_id`),
FOREIGN KEY (`currency_id`) REFERENCES `currency` (`id`) ON UPDATE CASCADE
FOREIGN KEY (`currency_id`) REFERENCES `currency` (`id`) ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

DROP TABLE IF EXISTS `taxe_ipr_configuration`;
Expand Down
2 changes: 1 addition & 1 deletion test/integration/trialBalance.js
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@ const helpers = require('./helpers');
* The /trial_balance API endpoint
*/
describe('(/journal/trialbalance) API endpoint', () => {
const GOOD_TXNS = [ 'a5a5f950-a4c9-47f0-9a9a-2bfc3123e534' ] // TPA1
const GOOD_TXNS = ['a5a5f950-a4c9-47f0-9a9a-2bfc3123e534']; // TPA1
const EMPTY_TXNS = [];
const ERROR_TXNS = ['3688e9ce-85ea-4b5c-9144-688177edcb63']; // TRANS5
const POSTING_TXNS = ['a5a5f950-a4c9-47f0-9a9a-2bfc3123e534']; // TPA1
Expand Down

0 comments on commit 227097a

Please sign in to comment.