Skip to content

Commit e883947

Browse files
budaidevadamsaghy
authored andcommitted
FINERACT-2466: fix trial balance report
1 parent 6875645 commit e883947

File tree

5 files changed

+750
-0
lines changed

5 files changed

+750
-0
lines changed

fineract-provider/src/main/resources/db/changelog/tenant/changelog-tenant.xml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -228,4 +228,5 @@
228228
<include file="parts/0207_add_allow_full_term_for_tranche.xml" relativeToChangelogFile="true" />
229229
<include file="parts/0208_trial_balance_summary_with_asset_owner_journal_entry_aggregation_fix.xml" relativeToChangelogFile="true" />
230230
<include file="parts/0209_transaction_summary_with_asset_owner_and_from_asset_owner_id_for_asset_sales.xml" relativeToChangelogFile="true" />
231+
<include file="parts/0210_trial_balance_summary_fix_external_owners_and_aggregation.xml" relativeToChangelogFile="true" />
231232
</databaseChangeLog>
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,242 @@
1+
<?xml version="1.0" encoding="UTF-8"?>
2+
<!--
3+
4+
Licensed to the Apache Software Foundation (ASF) under one
5+
or more contributor license agreements. See the NOTICE file
6+
distributed with this work for additional information
7+
regarding copyright ownership. The ASF licenses this file
8+
to you under the Apache License, Version 2.0 (the
9+
"License"); you may not use this file except in compliance
10+
with the License. You may obtain a copy of the License at
11+
12+
http://www.apache.org/licenses/LICENSE-2.0
13+
14+
Unless required by applicable law or agreed to in writing,
15+
software distributed under the License is distributed on an
16+
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
17+
KIND, either express or implied. See the License for the
18+
specific language governing permissions and limitations
19+
under the License.
20+
21+
-->
22+
<databaseChangeLog xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
23+
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
24+
xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-4.3.xsd">
25+
26+
<changeSet author="fineract" id="trial-balance-summary-with-asset-owner-update-5">
27+
<update tableName="stretchy_report">
28+
<column name="report_sql">
29+
<![CDATA[
30+
WITH retained_earning AS (
31+
SELECT DISTINCT
32+
'${endDate}' AS postingdate,
33+
lp.name AS product,
34+
gl_code AS glacct,
35+
COALESCE((SELECT name FROM acc_gl_account WHERE gl_code = e.gl_code), '') AS description,
36+
COALESCE(e.owner_external_id, 'self') AS assetowner,
37+
SUM(opening_balance_amount) AS beginningbalance,
38+
0 AS debitmovement,
39+
0 AS creditmovement,
40+
SUM(opening_balance_amount) AS endingbalance
41+
FROM acc_gl_journal_entry_annual_summary e, m_product_loan lp
42+
WHERE e.office_id = ${officeId}
43+
AND lp.id = product_id
44+
AND EXTRACT(YEAR FROM e.year_end_date) < EXTRACT(YEAR FROM CAST('${endDate}' AS DATE))
45+
GROUP BY gl_code, lp.name, office_id, owner_external_id
46+
),
47+
aggregated_date AS (
48+
SELECT MAX(aggregated_on_date_to) AS latest
49+
FROM m_journal_entry_aggregation_tracking
50+
WHERE aggregated_on_date_to < '${endDate}'
51+
),
52+
summary_snapshot_baseline_data AS (
53+
SELECT
54+
lp.NAME AS productname,
55+
acc_gl_account.gl_code AS glcode,
56+
acc_gl_account.NAME AS glname,
57+
CASE WHEN ags.external_owner_id IS NULL THEN 0 ELSE ags.external_owner_id END AS assetowner,
58+
SUM(ags.debit_amount) AS debitamount,
59+
SUM(ags.credit_amount) AS creditamount
60+
FROM acc_gl_account
61+
JOIN m_journal_entry_aggregation_summary ags ON acc_gl_account.id = ags.gl_account_id
62+
JOIN m_product_loan lp ON lp.id = ags.product_id
63+
WHERE ags.entity_type_enum = 1
64+
AND ags.manual_entry = FALSE
65+
AND ags.aggregated_on_date <= (SELECT latest FROM aggregated_date)
66+
AND (ags.office_id = ${officeId})
67+
GROUP BY productname, glcode, glname, assetowner
68+
),
69+
post_snapshot_delta_data AS (
70+
SELECT
71+
lp.NAME AS productname,
72+
acc_gl_account.gl_code AS glcode,
73+
acc_gl_account.NAME AS glname,
74+
CASE WHEN aw.owner_id IS NULL THEN 0 ELSE aw.owner_id END AS assetowner,
75+
SUM(CASE WHEN acc_gl_journal_entry.type_enum = 2 THEN amount ELSE 0 END) AS debitamount,
76+
SUM(CASE WHEN acc_gl_journal_entry.type_enum = 1 THEN amount ELSE 0 END) AS creditamount
77+
FROM acc_gl_account
78+
JOIN acc_gl_journal_entry ON acc_gl_account.id = acc_gl_journal_entry.account_id
79+
JOIN m_loan m ON m.id = acc_gl_journal_entry.entity_id
80+
JOIN m_product_loan lp ON lp.id = m.product_id
81+
LEFT JOIN m_external_asset_owner_journal_entry_mapping aw ON aw.journal_entry_id = acc_gl_journal_entry.id
82+
WHERE acc_gl_journal_entry.entity_type_enum = 1
83+
AND acc_gl_journal_entry.manual_entry = FALSE
84+
AND (
85+
(SELECT latest FROM aggregated_date) IS NULL
86+
OR acc_gl_journal_entry.submitted_on_date > (SELECT latest FROM aggregated_date)
87+
)
88+
AND acc_gl_journal_entry.submitted_on_date < '${endDate}'
89+
AND (acc_gl_journal_entry.office_id = ${officeId})
90+
GROUP BY productname, glcode, glname, assetowner
91+
),
92+
merged_historical_data AS (
93+
SELECT
94+
COALESCE(s.productname, p.productname) AS productname,
95+
COALESCE(s.glcode, p.glcode) AS glcode,
96+
COALESCE(s.glname, p.glname) AS glname,
97+
COALESCE(s.assetowner, p.assetowner, 0) AS assetowner,
98+
COALESCE(s.debitamount, 0) + COALESCE(p.debitamount, 0) AS debitamount,
99+
COALESCE(s.creditamount, 0) + COALESCE(p.creditamount, 0) AS creditamount
100+
FROM summary_snapshot_baseline_data s
101+
LEFT JOIN post_snapshot_delta_data p
102+
ON s.glcode = p.glcode
103+
AND s.productname = p.productname
104+
AND s.assetowner = p.assetowner
105+
106+
UNION ALL
107+
108+
SELECT
109+
p.productname AS productname,
110+
p.glcode AS glcode,
111+
p.glname AS glname,
112+
COALESCE(p.assetowner, 0) AS assetowner,
113+
COALESCE(p.debitamount, 0) AS debitamount,
114+
COALESCE(p.creditamount, 0) AS creditamount
115+
FROM post_snapshot_delta_data p
116+
LEFT JOIN summary_snapshot_baseline_data s
117+
ON s.glcode = p.glcode
118+
AND s.productname = p.productname
119+
AND s.assetowner = p.assetowner
120+
WHERE s.glcode IS NULL
121+
),
122+
current_cob_data AS (
123+
SELECT
124+
lp.name AS productname,
125+
account_id,
126+
acc_gl_account.gl_code AS glcode,
127+
acc_gl_account.name AS glname,
128+
CASE WHEN aw.owner_id IS NULL THEN 0 ELSE aw.owner_id END AS assetowner,
129+
SUM(CASE WHEN acc_gl_journal_entry.type_enum = 2 THEN amount ELSE 0 END) AS debitamount,
130+
SUM(CASE WHEN acc_gl_journal_entry.type_enum = 1 THEN amount ELSE 0 END) AS creditamount
131+
FROM acc_gl_journal_entry
132+
JOIN acc_gl_account ON acc_gl_account.id = acc_gl_journal_entry.account_id
133+
JOIN m_loan m ON m.id = acc_gl_journal_entry.entity_id
134+
JOIN m_product_loan lp ON lp.id = m.product_id
135+
LEFT JOIN m_external_asset_owner_journal_entry_mapping aw ON aw.journal_entry_id = acc_gl_journal_entry.id
136+
WHERE acc_gl_journal_entry.entity_type_enum = 1
137+
AND acc_gl_journal_entry.manual_entry = FALSE
138+
AND acc_gl_journal_entry.submitted_on_date = '${endDate}'
139+
AND (acc_gl_journal_entry.office_id = ${officeId})
140+
GROUP BY productname, account_id, glcode, glname, assetowner
141+
)
142+
143+
SELECT *
144+
FROM (
145+
SELECT *
146+
FROM retained_earning
147+
WHERE glacct = (SELECT gl_code FROM acc_gl_account WHERE name = 'Retained Earnings Prior Year')
148+
149+
UNION
150+
151+
SELECT
152+
txnreport.postingdate,
153+
txnreport.product,
154+
txnreport.glacct,
155+
txnreport.description,
156+
txnreport.assetowner,
157+
(COALESCE(txnreport.beginningbalance, 0) + COALESCE(summary.beginningbalance, 0)) AS beginningbalance,
158+
txnreport.debitmovement AS debitmovement,
159+
txnreport.creditmovement AS creditmovement,
160+
(COALESCE(txnreport.endingbalance, 0) + COALESCE(summary.beginningbalance, 0)) AS endingbalance
161+
FROM (
162+
SELECT *
163+
FROM (
164+
SELECT DISTINCT
165+
'${endDate}' AS postingdate,
166+
loan.pname AS product,
167+
loan.gl_code AS glacct,
168+
loan.glname AS description,
169+
COALESCE((SELECT external_id FROM m_external_asset_owner WHERE id = loan.assetowner), 'self') AS assetowner,
170+
loan.openingbalance AS beginningbalance,
171+
(loan.debitamount * 1) AS debitmovement,
172+
(loan.creditamount * -1) AS creditmovement,
173+
(loan.openingbalance + loan.debitamount - loan.creditamount) AS endingbalance
174+
FROM (
175+
SELECT DISTINCT
176+
g.pname AS pname,
177+
g.gl_code AS gl_code,
178+
g.glname AS glname,
179+
COALESCE(mh.assetowner, c.assetowner, 0) AS assetowner,
180+
COALESCE(mh.debitamount, 0) - COALESCE(mh.creditamount, 0) AS openingbalance,
181+
COALESCE(c.debitamount, 0) AS debitamount,
182+
COALESCE(c.creditamount, 0) AS creditamount
183+
FROM (
184+
SELECT DISTINCT ag.gl_code, ag.id, pl.NAME AS pname, ag.NAME AS glname
185+
FROM acc_gl_account ag
186+
JOIN acc_product_mapping am ON am.gl_account_id = ag.id AND am.product_type = 1
187+
JOIN m_product_loan pl ON pl.id = am.product_id
188+
) g
189+
LEFT JOIN merged_historical_data mh
190+
ON g.gl_code = mh.glcode
191+
AND mh.productname = g.pname
192+
LEFT JOIN current_cob_data c
193+
ON g.gl_code = c.glcode
194+
AND c.productname = g.pname
195+
AND mh.assetowner = c.assetowner
196+
197+
UNION ALL
198+
199+
SELECT DISTINCT
200+
c.productname AS pname,
201+
c.glcode AS gl_code,
202+
c.glname AS glname,
203+
COALESCE(c.assetowner, 0) AS assetowner,
204+
0 AS openingbalance,
205+
COALESCE(c.debitamount, 0) AS debitamount,
206+
COALESCE(c.creditamount, 0) AS creditamount
207+
FROM current_cob_data c
208+
LEFT JOIN (
209+
SELECT g3.gl_code, g3.pname, mh.assetowner
210+
FROM (
211+
SELECT DISTINCT ag.gl_code, pl.NAME AS pname
212+
FROM acc_gl_account ag
213+
JOIN acc_product_mapping am ON am.gl_account_id = ag.id AND am.product_type = 1
214+
JOIN m_product_loan pl ON pl.id = am.product_id
215+
) g3
216+
LEFT JOIN merged_historical_data mh
217+
ON g3.gl_code = mh.glcode
218+
AND mh.productname = g3.pname
219+
) matched
220+
ON matched.gl_code = c.glcode
221+
AND matched.pname = c.productname
222+
AND matched.assetowner = c.assetowner
223+
WHERE matched.gl_code IS NULL
224+
) loan
225+
) a
226+
) AS txnreport
227+
LEFT JOIN retained_earning summary
228+
ON txnreport.glacct = summary.glacct
229+
AND txnreport.assetowner = summary.assetowner
230+
AND summary.product = txnreport.product
231+
) report
232+
WHERE report.endingbalance != 0
233+
OR report.debitmovement != 0
234+
OR report.creditmovement != 0
235+
ORDER BY glacct
236+
237+
]]>
238+
</column>
239+
<where>report_name='Trial Balance Summary Report with Asset Owner'</where>
240+
</update>
241+
</changeSet>
242+
</databaseChangeLog>

integration-tests/src/test/java/org/apache/fineract/integrationtests/client/feign/helpers/FeignAccountHelper.java

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -71,6 +71,12 @@ private Account createAccount(String name, String glCode, String type) {
7171
return new Account(account.getId().intValue(), getAccountType(type));
7272
}
7373

74+
public String getGlCode(Account account) {
75+
GetGLAccountsResponse response = ok(
76+
() -> fineractClient.generalLedgerAccount().retreiveAccount(account.getAccountID().longValue(), Collections.emptyMap()));
77+
return response.getGlCode();
78+
}
79+
7480
private Integer getAccountTypeId(String type) {
7581
return switch (type) {
7682
case "ASSET" -> 1;
Lines changed: 74 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,74 @@
1+
/**
2+
* Licensed to the Apache Software Foundation (ASF) under one
3+
* or more contributor license agreements. See the NOTICE file
4+
* distributed with this work for additional information
5+
* regarding copyright ownership. The ASF licenses this file
6+
* to you under the Apache License, Version 2.0 (the
7+
* "License"); you may not use this file except in compliance
8+
* with the License. You may obtain a copy of the License at
9+
*
10+
* http://www.apache.org/licenses/LICENSE-2.0
11+
*
12+
* Unless required by applicable law or agreed to in writing,
13+
* software distributed under the License is distributed on an
14+
* "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
15+
* KIND, either express or implied. See the License for the
16+
* specific language governing permissions and limitations
17+
* under the License.
18+
*/
19+
package org.apache.fineract.integrationtests.client.feign.helpers;
20+
21+
import static org.apache.fineract.client.feign.util.FeignCalls.ok;
22+
23+
import java.time.Duration;
24+
import java.time.Instant;
25+
import java.time.OffsetDateTime;
26+
import java.time.temporal.ChronoUnit;
27+
import java.util.List;
28+
import org.apache.fineract.client.feign.FineractFeignClient;
29+
import org.apache.fineract.client.feign.util.FeignCalls;
30+
import org.apache.fineract.client.models.ExecuteJobRequest;
31+
import org.apache.fineract.client.models.GetJobsResponse;
32+
import org.apache.fineract.client.models.JobDetailHistoryData;
33+
import org.awaitility.Awaitility;
34+
35+
public class FeignSchedulerHelper {
36+
37+
private final FineractFeignClient fineractClient;
38+
39+
public FeignSchedulerHelper(FineractFeignClient fineractClient) {
40+
this.fineractClient = fineractClient;
41+
}
42+
43+
public void stopScheduler() {
44+
FeignCalls.executeVoid(() -> fineractClient.scheduler().changeSchedulerStatus("stop"));
45+
}
46+
47+
public void startScheduler() {
48+
FeignCalls.executeVoid(() -> fineractClient.scheduler().changeSchedulerStatus("start"));
49+
}
50+
51+
public void executeAndAwaitJob(String jobDisplayName) {
52+
stopScheduler();
53+
54+
List<GetJobsResponse> allJobs = ok(() -> fineractClient.schedulerJob().retrieveAll8());
55+
GetJobsResponse targetJob = allJobs.stream().filter(j -> jobDisplayName.equals(j.getDisplayName())).findFirst()
56+
.orElseThrow(() -> new RuntimeException("Job not found: " + jobDisplayName));
57+
58+
Instant beforeExecuteTime = Instant.now().truncatedTo(ChronoUnit.SECONDS);
59+
FeignCalls.executeVoid(() -> fineractClient.schedulerJob().executeJob(targetJob.getJobId(), "executeJob", new ExecuteJobRequest()));
60+
61+
Awaitility.await().atMost(Duration.ofMinutes(2)).pollInterval(Duration.ofSeconds(1)).pollDelay(Duration.ofSeconds(1)).until(() -> {
62+
GetJobsResponse job = ok(() -> fineractClient.schedulerJob().retrieveOne5(targetJob.getJobId()));
63+
JobDetailHistoryData history = job.getLastRunHistory();
64+
if (history == null || history.getJobRunStartTime() == null) {
65+
return false;
66+
}
67+
OffsetDateTime startTime = history.getJobRunStartTime();
68+
if (startTime.toInstant().isBefore(beforeExecuteTime)) {
69+
return false;
70+
}
71+
return history.getJobRunEndTime() != null && !history.getJobRunEndTime().toInstant().isBefore(startTime.toInstant());
72+
});
73+
}
74+
}

0 commit comments

Comments
 (0)