blob: 0453f49e1b8007ce61025f153bf808852e54a953 [file] [log] [blame]
<?xml version="1.0" encoding="UTF-8"?>
<!--
Licensed to the Apache Software Foundation (ASF) under one
or more contributor license agreements. See the NOTICE file
distributed with this work for additional information
regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
http://www.apache.org/licenses/LICENSE-2.0
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
<databaseChangeLog xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-4.3.xsd">
<!-- Transaction Balance With Asset Transfer Report -->
<changeSet author="fineract" id="1">
<update tableName="stretchy_report">
<column name="report_sql" value="select *
from (SELECT distinct '${endDate}' AS postingdate,
loan.pname AS product,
loan.gl_code AS glacct,
loan.glname AS description,
COALESCE((select external_id from m_external_asset_owner where id = loan.assetowner),
'self') as assetowner,
loan.openingbalance AS beginningbalance,
(loan.debitamount * 1) AS debitmovement,
(loan.creditamount * -1) AS creditmovement,
(loan.openingbalance + loan.debitamount - loan.creditamount) AS endingbalance
FROM (SELECT distinct COALESCE(g.pname, loanproduct.productname) pname,
COALESCE(g.gl_code, loanproduct.glcode) gl_code,
COALESCE(g.glname, loanproduct.glname) glname,
COALESCE(debits.assetowner, loanproduct.assetowner) assetowner,
COALESCE(debits.debitamount, 0) - COALESCE(debits.creditamount, 0) AS openingbalance,
COALESCE(loanproduct.debitamount, 0) AS debitamount,
COALESCE(loanproduct.creditamount, 0) AS creditamount
FROM (SELECT distinct ag.gl_code, ag.id, pl.NAME AS pname, ag.NAME AS glname
FROM acc_gl_account ag
JOIN acc_product_mapping am ON am.gl_account_id = ag.id AND am.product_type = 1
JOIN m_product_loan pl ON pl.id = am.product_id) g
LEFT JOIN (SELECT lp.NAME AS productname,
acc_gl_account.gl_code AS glcode,
acc_gl_account.NAME AS glname,
case when aw.owner_id is null then 0 else aw.owner_id end assetowner,
Sum(CASE WHEN acc_gl_journal_entry.type_enum = 2 THEN amount ELSE 0 END) AS debitamount,
Sum(CASE WHEN acc_gl_journal_entry.type_enum = 1 THEN amount ELSE 0 END) AS creditamount
FROM acc_gl_account
JOIN acc_gl_journal_entry
ON acc_gl_account.id = acc_gl_journal_entry.account_id
JOIN m_loan m ON m.id = acc_gl_journal_entry.entity_id
JOIN m_product_loan lp ON lp.id = m.product_id
left join m_external_asset_owner_journal_entry_mapping aw
on aw.journal_entry_id = acc_gl_journal_entry.id
WHERE acc_gl_journal_entry.entity_type_enum = 1
AND acc_gl_journal_entry.manual_entry = false
AND acc_gl_journal_entry.submitted_on_date &lt; '${endDate}'
AND (acc_gl_journal_entry.office_id = ${officeId})
GROUP BY productname, glcode, glname, assetowner
ORDER BY glcode) debits ON g.gl_code = debits.glcode AND debits.productname = g.pname
full outer join (select lp.name as productname,
account_id,
acc_gl_account.gl_code as glcode,
acc_gl_account.name as glname,
case when aw.owner_id is null then 0 else aw.owner_id end assetowner,
sum(case when acc_gl_journal_entry.type_enum = 2 then amount else 0 end) as debitamount,
sum(case when acc_gl_journal_entry.type_enum = 1 then amount else 0 end) as creditamount
from acc_gl_journal_entry
join acc_gl_account on acc_gl_account.id = acc_gl_journal_entry.account_id
join m_loan m on m.id = acc_gl_journal_entry.entity_id
join m_product_loan lp on lp.id = m.product_id
left join m_external_asset_owner_journal_entry_mapping aw
on aw.journal_entry_id = acc_gl_journal_entry.id
where acc_gl_journal_entry.entity_type_enum = 1
and acc_gl_journal_entry.manual_entry = false
and acc_gl_journal_entry.submitted_on_date = '${endDate}'
and (acc_gl_journal_entry.office_id = ${officeId})
group by productname, account_id, glcode, glname, assetowner
order by glcode) loanproduct
on g.gl_code = loanproduct.glcode and loanproduct.productname = g.pname and
debits.assetowner = loanproduct.assetowner) loan) a
where a.endingbalance != 0
or a.debitmovement != 0
or a.creditmovement != 0"/>
<where>report_name='Trial Balance Summary Report with Asset Owner'</where>
</update>
</changeSet>
</databaseChangeLog>