From eec2e7e833197d85a88a825e988922a0d64437ff Mon Sep 17 00:00:00 2001 From: Khushi Rawat <142375893+khushi8112@users.noreply.github.com> Date: Sun, 23 Mar 2025 18:38:06 +0530 Subject: [PATCH] fix: correct accumulated depreciation calculation for disposed assets (#46660) --- .../asset_depreciations_and_balances.py | 250 +++++++++--------- 1 file changed, 125 insertions(+), 125 deletions(-) diff --git a/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.py b/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.py index 5229839bec6..cdeddf3d38b 100644 --- a/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.py +++ b/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.py @@ -145,6 +145,130 @@ def get_asset_categories_for_grouped_by_category(filters): ) +def get_assets_for_grouped_by_category(filters): + condition = "" + if filters.get("asset_category"): + condition = f" and a.asset_category = '{filters.get('asset_category')}'" + finance_book_filter = "" + if filters.get("finance_book"): + finance_book_filter += " and ifnull(gle.finance_book, '')=%(finance_book)s" + condition += " and exists (select 1 from `tabAsset Depreciation Schedule` ads where ads.asset = a.name and ads.finance_book = %(finance_book)s)" + + # nosemgrep + return frappe.db.sql( + f""" + SELECT results.asset_category, + sum(results.accumulated_depreciation_as_on_from_date) as accumulated_depreciation_as_on_from_date, + sum(results.depreciation_eliminated_via_reversal) as depreciation_eliminated_via_reversal, + sum(results.depreciation_eliminated_during_the_period) as depreciation_eliminated_during_the_period, + sum(results.depreciation_amount_during_the_period) as depreciation_amount_during_the_period + from (SELECT a.asset_category, + ifnull(sum(case when gle.posting_date < %(from_date)s and (ifnull(a.disposal_date, 0) = 0 or a.disposal_date >= %(from_date)s) then + gle.debit + else + 0 + end), 0) as accumulated_depreciation_as_on_from_date, + ifnull(sum(case when gle.posting_date <= %(to_date)s and ifnull(a.disposal_date, 0) = 0 then + gle.credit + else + 0 + end), 0) as depreciation_eliminated_via_reversal, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s and gle.posting_date <= a.disposal_date then + gle.debit + else + 0 + end), 0) as depreciation_eliminated_during_the_period, + ifnull(sum(case when gle.posting_date >= %(from_date)s and gle.posting_date <= %(to_date)s + and (ifnull(a.disposal_date, 0) = 0 or gle.posting_date <= a.disposal_date) then + gle.debit + else + 0 + end), 0) as depreciation_amount_during_the_period + from `tabGL Entry` gle + join `tabAsset` a on + gle.against_voucher = a.name + join `tabAsset Category Account` aca on + aca.parent = a.asset_category and aca.company_name = %(company)s + join `tabCompany` company on + company.name = %(company)s + where + a.docstatus=1 + and a.company=%(company)s + and a.purchase_date <= %(to_date)s + and gle.is_cancelled = 0 + and gle.account = ifnull(aca.depreciation_expense_account, company.depreciation_expense_account) + {condition} {finance_book_filter} + group by a.asset_category + union + SELECT a.asset_category, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and a.disposal_date < %(from_date)s then + 0 + else + a.opening_accumulated_depreciation + end), 0) as accumulated_depreciation_as_on_from_date, + 0 as depreciation_eliminated_via_reversal, + ifnull(sum(case when a.disposal_date >= %(from_date)s and a.disposal_date <= %(to_date)s then + a.opening_accumulated_depreciation + else + 0 + end), 0) as depreciation_eliminated_during_the_period, + 0 as depreciation_amount_during_the_period + from `tabAsset` a + where a.docstatus=1 and a.company=%(company)s and a.purchase_date <= %(to_date)s {condition} + group by a.asset_category) as results + group by results.asset_category + """, + { + "to_date": filters.to_date, + "from_date": filters.from_date, + "company": filters.company, + "finance_book": filters.get("finance_book", ""), + }, + as_dict=1, + ) + + +def get_group_by_asset_data(filters): + data = [] + + asset_details = get_asset_details_for_grouped_by_category(filters) + assets = get_assets_for_grouped_by_asset(filters) + + for asset_detail in asset_details: + row = frappe._dict() + row.update(asset_detail) + + row.value_as_on_to_date = ( + flt(row.value_as_on_from_date) + + flt(row.value_of_new_purchase) + - flt(row.value_of_sold_asset) + - flt(row.value_of_scrapped_asset) + - flt(row.value_of_capitalized_asset) + ) + + row.update(next(asset for asset in assets if asset["asset"] == asset_detail.get("name", ""))) + + row.accumulated_depreciation_as_on_to_date = ( + flt(row.accumulated_depreciation_as_on_from_date) + + flt(row.depreciation_amount_during_the_period) + - flt(row.depreciation_eliminated_during_the_period) + - flt(row.depreciation_eliminated_via_reversal) + ) + + row.net_asset_value_as_on_from_date = flt(row.value_as_on_from_date) - flt( + row.accumulated_depreciation_as_on_from_date + ) + + row.net_asset_value_as_on_to_date = flt(row.value_as_on_to_date) - flt( + row.accumulated_depreciation_as_on_to_date + ) + + data.append(row) + + return data + + def get_asset_details_for_grouped_by_category(filters): condition = "" if filters.get("asset"): @@ -224,130 +348,6 @@ def get_asset_details_for_grouped_by_category(filters): ) -def get_group_by_asset_data(filters): - data = [] - - asset_details = get_asset_details_for_grouped_by_category(filters) - assets = get_assets_for_grouped_by_asset(filters) - - for asset_detail in asset_details: - row = frappe._dict() - row.update(asset_detail) - - row.value_as_on_to_date = ( - flt(row.value_as_on_from_date) - + flt(row.value_of_new_purchase) - - flt(row.value_of_sold_asset) - - flt(row.value_of_scrapped_asset) - - flt(row.value_of_capitalized_asset) - ) - - row.update(next(asset for asset in assets if asset["asset"] == asset_detail.get("name", ""))) - - row.accumulated_depreciation_as_on_to_date = ( - flt(row.accumulated_depreciation_as_on_from_date) - + flt(row.depreciation_amount_during_the_period) - - flt(row.depreciation_eliminated_during_the_period) - - flt(row.depreciation_eliminated_via_reversal) - ) - - row.net_asset_value_as_on_from_date = flt(row.value_as_on_from_date) - flt( - row.accumulated_depreciation_as_on_from_date - ) - - row.net_asset_value_as_on_to_date = flt(row.value_as_on_to_date) - flt( - row.accumulated_depreciation_as_on_to_date - ) - - data.append(row) - - return data - - -def get_assets_for_grouped_by_category(filters): - condition = "" - if filters.get("asset_category"): - condition = f" and a.asset_category = '{filters.get('asset_category')}'" - finance_book_filter = "" - if filters.get("finance_book"): - finance_book_filter += " and ifnull(gle.finance_book, '')=%(finance_book)s" - condition += " and exists (select 1 from `tabAsset Depreciation Schedule` ads where ads.asset = a.name and ads.finance_book = %(finance_book)s)" - - # nosemgrep - return frappe.db.sql( - f""" - SELECT results.asset_category, - sum(results.accumulated_depreciation_as_on_from_date) as accumulated_depreciation_as_on_from_date, - sum(results.depreciation_eliminated_via_reversal) as depreciation_eliminated_via_reversal, - sum(results.depreciation_eliminated_during_the_period) as depreciation_eliminated_during_the_period, - sum(results.depreciation_amount_during_the_period) as depreciation_amount_during_the_period - from (SELECT a.asset_category, - ifnull(sum(case when gle.posting_date < %(from_date)s and (ifnull(a.disposal_date, 0) = 0 or a.disposal_date >= %(from_date)s) then - gle.debit - else - 0 - end), 0) as accumulated_depreciation_as_on_from_date, - ifnull(sum(case when gle.posting_date <= %(to_date)s and ifnull(a.disposal_date, 0) = 0 then - gle.credit - else - 0 - end), 0) as depreciation_eliminated_via_reversal, - ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and a.disposal_date >= %(from_date)s - and a.disposal_date <= %(to_date)s and gle.posting_date <= a.disposal_date then - gle.debit - else - 0 - end), 0) as depreciation_eliminated_during_the_period, - ifnull(sum(case when gle.posting_date >= %(from_date)s and gle.posting_date <= %(to_date)s - and (ifnull(a.disposal_date, 0) = 0 or gle.posting_date <= a.disposal_date) then - gle.debit - else - 0 - end), 0) as depreciation_amount_during_the_period - from `tabGL Entry` gle - join `tabAsset` a on - gle.against_voucher = a.name - join `tabAsset Category Account` aca on - aca.parent = a.asset_category and aca.company_name = %(company)s - join `tabCompany` company on - company.name = %(company)s - where - a.docstatus=1 - and a.company=%(company)s - and a.purchase_date <= %(to_date)s - and gle.is_cancelled = 0 - and gle.account = ifnull(aca.depreciation_expense_account, company.depreciation_expense_account) - {condition} {finance_book_filter} - group by a.asset_category - union - SELECT a.asset_category, - ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and (a.disposal_date < %(from_date)s or a.disposal_date > %(to_date)s) then - 0 - else - a.opening_accumulated_depreciation - end), 0) as accumulated_depreciation_as_on_from_date, - 0 as depreciation_eliminated_via_reversal, - ifnull(sum(case when a.disposal_date >= %(from_date)s and a.disposal_date <= %(to_date)s then - a.opening_accumulated_depreciation - else - 0 - end), 0) as depreciation_eliminated_during_the_period, - 0 as depreciation_amount_during_the_period - from `tabAsset` a - where a.docstatus=1 and a.company=%(company)s and a.purchase_date <= %(to_date)s {condition} - group by a.asset_category) as results - group by results.asset_category - """, - { - "to_date": filters.to_date, - "from_date": filters.from_date, - "company": filters.company, - "finance_book": filters.get("finance_book", ""), - }, - as_dict=1, - ) - - def get_assets_for_grouped_by_asset(filters): condition = "" if filters.get("asset"): @@ -405,7 +405,7 @@ def get_assets_for_grouped_by_asset(filters): group by a.name union SELECT a.name as name, - ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and (a.disposal_date < %(from_date)s or a.disposal_date > %(to_date)s) then + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 and a.disposal_date < %(from_date)s then 0 else a.opening_accumulated_depreciation