From 2fe9fa7ef766dfa9650d26c7f4c99424cfff1417 Mon Sep 17 00:00:00 2001 From: Khushi Rawat <142375893+khushi8112@users.noreply.github.com> Date: Fri, 4 Apr 2025 10:39:16 +0530 Subject: [PATCH] feat: asset filter in asset depreciation and balances report (#46848) --- .../asset_depreciations_and_balances.js | 15 + .../asset_depreciations_and_balances.py | 394 +++++++++++++++--- 2 files changed, 348 insertions(+), 61 deletions(-) diff --git a/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.js b/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.js index 88ec0881585..49771d7ebe9 100644 --- a/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.js +++ b/erpnext/accounts/report/asset_depreciations_and_balances/asset_depreciations_and_balances.js @@ -25,11 +25,26 @@ frappe.query_reports["Asset Depreciations and Balances"] = { default: erpnext.utils.get_fiscal_year(frappe.datetime.get_today(), true)[2], reqd: 1, }, + { + fieldname: "group_by", + label: __("Group By"), + fieldtype: "Select", + options: ["Asset Category", "Asset"], + default: "Asset Category", + }, { fieldname: "asset_category", label: __("Asset Category"), fieldtype: "Link", options: "Asset Category", + depends_on: "eval: doc.group_by == 'Asset Category'", + }, + { + fieldname: "asset", + label: __("Asset"), + fieldtype: "Link", + options: "Asset", + depends_on: "eval: doc.group_by == 'Asset'", }, ], }; 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 1754780e346..96495207444 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 @@ -14,21 +14,28 @@ def execute(filters=None): def get_data(filters): + if filters.get("group_by") == "Asset Category": + return get_group_by_asset_category_data(filters) + elif filters.get("group_by") == "Asset": + return get_group_by_asset_data(filters) + + +def get_group_by_asset_category_data(filters): data = [] - asset_categories = get_asset_categories(filters) - assets = get_assets(filters) + asset_categories = get_asset_categories_for_grouped_by_category(filters) + assets = get_assets_for_grouped_by_category(filters) for asset_category in asset_categories: row = frappe._dict() - # row.asset_category = asset_category row.update(asset_category) - row.cost_as_on_to_date = ( - flt(row.cost_as_on_from_date) - + flt(row.cost_of_new_purchase) - - flt(row.cost_of_sold_asset) - - flt(row.cost_of_scrapped_asset) + 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( @@ -38,17 +45,19 @@ def get_data(filters): if asset["asset_category"] == asset_category.get("asset_category", "") ) ) + 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.cost_as_on_from_date) - flt( + 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.cost_as_on_to_date) - flt( + row.net_asset_value_as_on_to_date = flt(row.value_as_on_to_date) - flt( row.accumulated_depreciation_as_on_to_date ) @@ -57,52 +66,71 @@ def get_data(filters): return data -def get_asset_categories(filters): +def get_asset_categories_for_grouped_by_category(filters): condition = "" if filters.get("asset_category"): - condition += " and asset_category = %(asset_category)s" + condition += " and a.asset_category = %(asset_category)s" + + # nosemgrep return frappe.db.sql( f""" - SELECT asset_category, - ifnull(sum(case when purchase_date < %(from_date)s then - case when ifnull(disposal_date, 0) = 0 or disposal_date >= %(from_date)s then - gross_purchase_amount + SELECT a.asset_category, + ifnull(sum(case when a.purchase_date < %(from_date)s then + case when ifnull(a.disposal_date, 0) = 0 or a.disposal_date >= %(from_date)s then + a.gross_purchase_amount else 0 end else 0 - end), 0) as cost_as_on_from_date, - ifnull(sum(case when purchase_date >= %(from_date)s then - gross_purchase_amount + end), 0) as value_as_on_from_date, + ifnull(sum(case when a.purchase_date >= %(from_date)s then + a.gross_purchase_amount else 0 - end), 0) as cost_of_new_purchase, - ifnull(sum(case when ifnull(disposal_date, 0) != 0 - and disposal_date >= %(from_date)s - and disposal_date <= %(to_date)s then - case when status = "Sold" then - gross_purchase_amount + end), 0) as value_of_new_purchase, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Sold" then + a.gross_purchase_amount else 0 end else 0 - end), 0) as cost_of_sold_asset, - ifnull(sum(case when ifnull(disposal_date, 0) != 0 - and disposal_date >= %(from_date)s - and disposal_date <= %(to_date)s then - case when status = "Scrapped" then - gross_purchase_amount + end), 0) as value_of_sold_asset, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Scrapped" then + a.gross_purchase_amount else 0 end else 0 - end), 0) as cost_of_scrapped_asset - from `tabAsset` - where docstatus=1 and company=%(company)s and purchase_date <= %(to_date)s {condition} - group by asset_category + end), 0) as value_of_scrapped_asset, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Capitalized" then + a.gross_purchase_amount + else + 0 + end + else + 0 + end), 0) as value_of_capitalized_asset + from `tabAsset` a + where a.docstatus=1 and a.company=%(company)s and a.purchase_date <= %(to_date)s {condition} + and not exists( + select 1 from `tabAsset Capitalization Asset Item` acai join `tabAsset Capitalization` ac on acai.parent=ac.name + where acai.asset = a.name + and ac.posting_date < %(from_date)s + and ac.docstatus=1 + ) + group by a.asset_category """, { "to_date": filters.to_date, @@ -114,14 +142,17 @@ def get_asset_categories(filters): ) -def get_assets(filters): +def get_assets_for_grouped_by_category(filters): condition = "" if filters.get("asset_category"): - condition = " and a.asset_category = '{}'".format(filters.get("asset_category")) + condition = f" and a.asset_category = '{filters.get('asset_category')}'" + + # 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, @@ -130,6 +161,11 @@ def get_assets(filters): 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 @@ -149,15 +185,22 @@ def get_assets(filters): 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.debit != 0 and gle.is_cancelled = 0 and gle.account = ifnull(aca.depreciation_expense_account, company.depreciation_expense_account) {0} + 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} 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 + 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 @@ -165,51 +208,272 @@ def get_assets(filters): 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 {0} + 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 - """.format(condition), - {"to_date": filters.to_date, "from_date": filters.from_date, "company": filters.company}, + """, + { + "to_date": filters.to_date, + "from_date": filters.from_date, + "company": filters.company, + }, + 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"): + condition += " and a.name = %(asset)s" + + # nosemgrep + return frappe.db.sql( + f""" + SELECT a.name, + ifnull(sum(case when a.purchase_date < %(from_date)s then + case when ifnull(a.disposal_date, 0) = 0 or a.disposal_date >= %(from_date)s then + a.gross_purchase_amount + else + 0 + end + else + 0 + end), 0) as value_as_on_from_date, + ifnull(sum(case when a.purchase_date >= %(from_date)s then + a.gross_purchase_amount + else + 0 + end), 0) as value_of_new_purchase, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Sold" then + a.gross_purchase_amount + else + 0 + end + else + 0 + end), 0) as value_of_sold_asset, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Scrapped" then + a.gross_purchase_amount + else + 0 + end + else + 0 + end), 0) as value_of_scrapped_asset, + ifnull(sum(case when ifnull(a.disposal_date, 0) != 0 + and a.disposal_date >= %(from_date)s + and a.disposal_date <= %(to_date)s then + case when a.status = "Capitalized" then + a.gross_purchase_amount + else + 0 + end + else + 0 + end), 0) as value_of_capitalized_asset + from `tabAsset` a + where a.docstatus=1 and a.company=%(company)s and a.purchase_date <= %(to_date)s {condition} + and not exists( + select 1 from `tabAsset Capitalization Asset Item` acai join `tabAsset Capitalization` ac on acai.parent=ac.name + where acai.asset = a.name + and ac.posting_date < %(from_date)s + and ac.docstatus=1 + ) + group by a.name + """, + { + "to_date": filters.to_date, + "from_date": filters.from_date, + "company": filters.company, + "asset": filters.get("asset"), + }, + as_dict=1, + ) + + +def get_assets_for_grouped_by_asset(filters): + condition = "" + if filters.get("asset"): + condition = f" and a.name = '{filters.get('asset')}'" + + # nosemgrep + return frappe.db.sql( + f""" + SELECT results.name as asset, + 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.name as name, + 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} + 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 then + 0 + else + a.opening_accumulated_depreciation + end), 0) as accumulated_depreciation_as_on_from_date, + 0 as depreciation_as_on_from_date_credit, + 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.name) as results + group by results.name + """, + { + "to_date": filters.to_date, + "from_date": filters.from_date, + "company": filters.company, + }, as_dict=1, ) def get_columns(filters): - return [ + columns = [] + + if filters.get("group_by") == "Asset Category": + columns.append( + { + "label": _("Asset Category"), + "fieldname": "asset_category", + "fieldtype": "Link", + "options": "Asset Category", + "width": 120, + } + ) + elif filters.get("group_by") == "Asset": + columns.append( + { + "label": _("Asset"), + "fieldname": "asset", + "fieldtype": "Link", + "options": "Asset", + "width": 120, + } + ) + + columns += [ { - "label": _("Asset Category"), - "fieldname": "asset_category", - "fieldtype": "Link", - "options": "Asset Category", - "width": 120, - }, - { - "label": _("Cost as on") + " " + formatdate(filters.day_before_from_date), - "fieldname": "cost_as_on_from_date", + "label": _("Value as on") + " " + formatdate(filters.day_before_from_date), + "fieldname": "value_as_on_from_date", "fieldtype": "Currency", "width": 140, }, { - "label": _("Cost of New Purchase"), - "fieldname": "cost_of_new_purchase", + "label": _("Value of New Purchase"), + "fieldname": "value_of_new_purchase", "fieldtype": "Currency", "width": 140, }, { - "label": _("Cost of Sold Asset"), - "fieldname": "cost_of_sold_asset", + "label": _("Value of Sold Asset"), + "fieldname": "value_of_sold_asset", "fieldtype": "Currency", "width": 140, }, { - "label": _("Cost of Scrapped Asset"), - "fieldname": "cost_of_scrapped_asset", + "label": _("Value of Scrapped Asset"), + "fieldname": "value_of_scrapped_asset", "fieldtype": "Currency", "width": 140, }, { - "label": _("Cost as on") + " " + formatdate(filters.to_date), - "fieldname": "cost_as_on_to_date", + "label": _("Value of New Capitalized Asset"), + "fieldname": "value_of_capitalized_asset", + "fieldtype": "Currency", + "width": 140, + }, + { + "label": _("Value as on") + " " + formatdate(filters.to_date), + "fieldname": "value_as_on_to_date", "fieldtype": "Currency", "width": 140, }, @@ -237,6 +501,12 @@ def get_columns(filters): "fieldtype": "Currency", "width": 270, }, + { + "label": _("Depreciation eliminated via reversal"), + "fieldname": "depreciation_eliminated_via_reversal", + "fieldtype": "Currency", + "width": 270, + }, { "label": _("Net Asset value as on") + " " + formatdate(filters.day_before_from_date), "fieldname": "net_asset_value_as_on_from_date", @@ -250,3 +520,5 @@ def get_columns(filters): "width": 200, }, ] + + return columns