FINERACT-1971: Transaction Summary Report with Asset Owner does not
report overpaid amount
diff --git a/fineract-provider/src/main/resources/db/changelog/tenant/changelog-tenant.xml b/fineract-provider/src/main/resources/db/changelog/tenant/changelog-tenant.xml
index 9425481..43e6b66 100644
--- a/fineract-provider/src/main/resources/db/changelog/tenant/changelog-tenant.xml
+++ b/fineract-provider/src/main/resources/db/changelog/tenant/changelog-tenant.xml
@@ -148,4 +148,5 @@
     <include file="parts/0126_add_loan_product_installment_level_delinquency.xml" relativeToChangelogFile="true" />
     <include file="parts/0127_client_name_length.xml" relativeToChangelogFile="true" />
     <include file="parts/0128_savings_audit.xml" relativeToChangelogFile="true" />
+    <include file="parts/0129_transaction_summary_with_asset_owner_report_overpaid_amount.xml" relativeToChangelogFile="true" />
 </databaseChangeLog>
diff --git a/fineract-provider/src/main/resources/db/changelog/tenant/parts/0129_transaction_summary_with_asset_owner_report_overpaid_amount.xml b/fineract-provider/src/main/resources/db/changelog/tenant/parts/0129_transaction_summary_with_asset_owner_report_overpaid_amount.xml
new file mode 100644
index 0000000..9201887
--- /dev/null
+++ b/fineract-provider/src/main/resources/db/changelog/tenant/parts/0129_transaction_summary_with_asset_owner_report_overpaid_amount.xml
@@ -0,0 +1,898 @@
+<?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">
+    <changeSet author="fineract" id="1">
+        <update tableName="stretchy_report">
+            <column name="report_sql"
+                    value="SELECT '${endDate}'                                                            AS TransactionDate,
+       a.product                                                               AS Product,
+       case
+           when a.transaction_type = 9999 then 'Asset Transfer'
+           when a.transaction_type = 99999 then 'Asset Buyback'
+           else (SELECT enum_message_property
+                 FROM r_enum_value
+                 WHERE enum_name = 'transaction_type_enum'
+                   and enum_id = a.transaction_type) end                       as TransactionType_Name,
+       (select value from m_payment_type where id = a.payment_type_id)         as PaymentType_Name,
+       a.chargetype                                                            as chargetype,
+       a.reversal_indicator                                                    AS Reversed,
+       a.Allocation_Type                                                       AS Allocation_Type,
+       (select code_value from m_code_value where id = a.charge_off_reason_id) AS Chargeoff_ReasonCode,
+       case
+           when a.transaction_type = 9999 then sum(a.amount) * + 1
+           when a.transaction_type = 99999 then sum(a.amount) * - 1
+           when a.transaction_type IN (2, 23, 21, 22, 24, 4, 5, 8, 6, 27, 9, 26) AND a.reversal_indicator = false
+               then sum(a.amount) * -1
+           when a.transaction_type IN (2, 23, 21, 22, 24, 4, 5, 8, 6, 27, 9, 26) AND a.reversal_indicator = true
+               then sum(a.amount) * + 1
+           when a.transaction_type IN (1, 10, 25, 20) AND a.reversal_indicator = false then sum(a.amount) * + 1
+           when a.transaction_type IN (1, 10, 25, 20) AND a.reversal_indicator = true
+               then sum(a.amount) * -1 end                                     AS Transaction_Amount,
+       (select external_id
+        from m_external_asset_owner
+        where id = a.asset_owner_id)                                           AS Asset_owner_id
+FROM (SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                     as chargetype,
+             false                                                                                  AS reversal_indicator,
+             'Principal'                                                                            AS Allocation_Type,
+             CASE
+                 when t.transaction_type_enum in (1) then (case when t.amount is null then 0 else t.amount end)
+                 else (case
+                           when t.principal_portion_derived is null then 0
+                           else t.principal_portion_derived end) end                                   amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                      as chargetype,
+             false                                                                                   AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             false                                                                                         AS reversal_indicator,
+             'Fees'                                                                                        AS Allocation_Type,
+             case when t.fee_charges_portion_derived is null then 0 else t.fee_charges_portion_derived end as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                              AS transactiondate,
+             t.id,
+             l.name                                                                    AS product,
+             t.transaction_type_enum                                                   AS transaction_type,
+             d.payment_type_id,
+             ''                                                                        as chargetype,
+             false                                                                     AS reversal_indicator,
+             'Penalty'                                                                 AS Allocation_Type,
+             case
+                 when t.penalty_charges_portion_derived is null then 0
+                 else t.penalty_charges_portion_derived end                            as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                               as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             false                                                                                         AS reversal_indicator,
+             'Unallocated Credit (UNC)'                                                                    AS Allocation_Type,
+             case when t.overpayment_portion_derived is null then 0 else t.overpayment_portion_derived end as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             null,
+             mc.name,
+             false                                                                                  AS reversal_indicator,
+             'Fees'                                                                                 AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = false
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = false
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             null,
+             mc.name,
+             false                                                                                  AS reversal_indicator,
+             'Penalty'                                                                              AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = true
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = false
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             null,
+             ''                                                                                      as chargetype,
+             false                                                                                   AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = false
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             mc.name,
+             false                                                                                  AS reversal_indicator,
+             'Fees'                                                                                 AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = false
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             mc.name,
+             false                                                                                  AS reversal_indicator,
+             'Penalty'                                                                              AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = true
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                      as chargetype,
+             false                                                                                   AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                              AS transactiondate,
+             t.id,
+             l.name                                                                                    AS product,
+             t.transaction_type_enum                                                                   AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                        as chargetype,
+             false                                                                                     AS reversal_indicator,
+             'Principal'                                                                               AS Allocation_Type,
+             case when t.principal_portion_derived is null then 0 else t.principal_portion_derived end AS amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                               as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                 AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             false                                                                                         AS reversal_indicator,
+             'Unallocated Credit (UNC)'                                                                    AS Allocation_Type,
+             case when t.overpayment_portion_derived is null then 0 else t.overpayment_portion_derived end AS amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.submitted_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                     as chargetype,
+             true                                                                                   AS reversal_indicator,
+             'Principal'                                                                            AS Allocation_Type,
+             CASE
+                 when t.transaction_type_enum in (1) then (case when t.amount is null then 0 else t.amount end)
+                 else (case
+                           when t.principal_portion_derived is null then 0
+                           else t.principal_portion_derived end) end                                   amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                      as chargetype,
+             true                                                                                    AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             true                                                                                          AS reversal_indicator,
+             'Fees'                                                                                        AS Allocation_Type,
+             case when t.fee_charges_portion_derived is null then 0 else t.fee_charges_portion_derived end as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                              AS transactiondate,
+             t.id,
+             l.name                                                                    AS product,
+             t.transaction_type_enum                                                   AS transaction_type,
+             d.payment_type_id,
+             ''                                                                        as chargetype,
+             true                                                                      AS reversal_indicator,
+             'Penalty'                                                                 AS Allocation_Type,
+             case
+                 when t.penalty_charges_portion_derived is null then 0
+                 else t.penalty_charges_portion_derived end                            as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                               as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             true                                                                                          AS reversal_indicator,
+             'Unallocated Credit (UNC)'                                                                    AS Allocation_Type,
+             case when t.overpayment_portion_derived is null then 0 else t.overpayment_portion_derived end as amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum not in (10, 26)
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             null,
+             mc.name,
+             true                                                                                   AS reversal_indicator,
+             'Fees'                                                                                 AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = false
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = true
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             null,
+             mc.name,
+             true                                                                                   AS reversal_indicator,
+             'Penalty'                                                                              AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = true
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = true
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             null,
+             ''                                                                                      as chargetype,
+             true                                                                                    AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 10
+        and t.is_reversed = true
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             mc.name,
+             true                                                                                   AS reversal_indicator,
+             'Fees'                                                                                 AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  as amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = false
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                           AS transactiondate,
+             t.id,
+             l.name                                                                                 AS product,
+             t.transaction_type_enum                                                                AS transaction_type,
+             d.payment_type_id,
+             mc.name,
+             true                                                                                   AS reversal_indicator,
+             'Penalty'                                                                              AS Allocation_Type,
+             case when pd.amount is null then 0 else pd.amount end                                  AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end              AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               join m_loan_charge_paid_by pd on pd.loan_transaction_id = t.id
+               join m_loan_charge c on c.id = pd.loan_charge_id
+               join m_charge mc on mc.id = c.charge_id and mc.is_penalty = true
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                            AS transactiondate,
+             t.id,
+             l.name                                                                                  AS product,
+             t.transaction_type_enum                                                                 AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                      as chargetype,
+             true                                                                                    AS reversal_indicator,
+             'Interest'                                                                              AS Allocation_Type,
+             case when t.interest_portion_derived is null then 0 else t.interest_portion_derived end AS amount,
+             case when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}' then e.owner_id end  as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end               AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                              AS transactiondate,
+             t.id,
+             l.name                                                                                    AS product,
+             t.transaction_type_enum                                                                   AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                        as chargetype,
+             true                                                                                      AS reversal_indicator,
+             'Principal'                                                                               AS Allocation_Type,
+             case when t.principal_portion_derived is null then 0 else t.principal_portion_derived end AS amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                               as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                 AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                                                                                  AS transactiondate,
+             t.id,
+             l.name                                                                                        AS product,
+             t.transaction_type_enum                                                                       AS transaction_type,
+             d.payment_type_id,
+             ''                                                                                            as chargetype,
+             true                                                                                          AS reversal_indicator,
+             'Unallocated Credit (UNC)'                                                                    AS Allocation_Type,
+             case when t.overpayment_portion_derived is null then 0 else t.overpayment_portion_derived end AS amount,
+             case
+                 when e.status = 'ACTIVE' and e.settlement_date &lt; '${endDate}'
+                     then e.owner_id end                                                                   as asset_owner_id,
+             case when t.transaction_type_enum = 27 then m.charge_off_reason_cv_id end                     AS charge_off_reason_id
+      FROM m_loan_transaction t
+               JOIN m_loan m ON m.id = t.loan_id
+               JOIN m_product_loan l ON l.id = m.product_id
+               left join m_payment_detail d on d.id = t.payment_detail_id
+               left join m_external_asset_owner_transfer e
+                         ON e.loan_id = t.loan_id and e.settlement_date &lt; '${endDate}' and
+                            e.effective_date_to &gt;= '${endDate}'
+      WHERE t.reversed_on_date = '${endDate}'
+        and t.transaction_type_enum = 26
+        and (t.office_id = ${officeId})
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             9999                                       AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Principal'                                AS Allocation_type,
+             dt.principal_outstanding_derived           AS amount,
+             t.owner_id                                 AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'ACTIVE'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.principal_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             9999                                       AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Interest'                                 AS Allocation_type,
+             dt.interest_outstanding_derived            AS amount,
+             t.owner_id                                 AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'ACTIVE'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.interest_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             9999                                       AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Fees'                                     AS Allocation_type,
+             dt.fee_charges_outstanding_derived         AS amount,
+             t.owner_id                                 AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'ACTIVE'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.fee_charges_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             9999                                       AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Penalty'                                  AS Allocation_type,
+             dt.penalty_charges_outstanding_derived     AS amount,
+             t.owner_id                                 AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'ACTIVE'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.penalty_charges_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             9999                                       AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Unallocated Credit (UNC)'                 AS Allocation_type,
+             dt.total_overpaid_derived                  AS amount,
+             t.owner_id                                 AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'ACTIVE'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.total_overpaid_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             99999                                      AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Principal'                                AS Allocation_type,
+             dt.principal_outstanding_derived           AS amount,
+             null                                       AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'BUYBACK'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.principal_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             99999                                      AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Interest'                                 AS Allocation_type,
+             dt.interest_outstanding_derived            AS amount,
+             null                                       AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'BUYBACK'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.interest_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             99999                                      AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Fees'                                     AS Allocation_type,
+             dt.fee_charges_outstanding_derived         AS amount,
+             null                                       AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'BUYBACK'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.fee_charges_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             99999                                      AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Penalty'                                  AS Allocation_type,
+             dt.penalty_charges_outstanding_derived     AS amount,
+             null                                       AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'BUYBACK'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.penalty_charges_outstanding_derived &gt; 0
+      UNION ALL
+      SELECT '${endDate}'                               AS transactiondate,
+             t.id,
+             p.name                                     AS product,
+             99999                                      AS transaction_type,
+             null,
+             ''                                         AS chargetype,
+             false                                      AS reversal_indicator,
+             'Unallocated Credit (UNC)'                 AS Allocation_type,
+             dt.total_overpaid_derived                  AS amount,
+             null                                       AS asset_owner_id,
+             null                                       AS charge_off_reason_id
+      FROM m_external_asset_owner_transfer t
+               JOIN m_loan l on l.id = t.loan_id
+               join m_client c on c.id = l.client_id
+               JOIN m_product_loan p ON p.id = l.product_id
+               JOIN m_external_asset_owner_transfer_details dt ON dt.asset_owner_transfer_id = t.id
+      WHERE t.status = 'BUYBACK'
+        and c.office_id = ${officeId}
+        and t.settlement_date = '${endDate}'
+        and dt.total_overpaid_derived &gt; 0) a
+GROUP BY a.transactiondate, a.product, a.transaction_type, a.payment_type_id, a.chargetype, a.reversal_indicator,
+         a.Allocation_Type, a.asset_owner_id, a.charge_off_reason_id
+order by 1, 2, 3, 4, 5, 6, 7"/>
+            <where>report_name='Transaction Summary Report with Asset Owner'</where>
+        </update>
+    </changeSet>
+</databaseChangeLog>