feat: Closing balance for period closing and reporting (#34257)

* feat: Introduce opening entry for reporting

(cherry picked from commit 9739d8b52a)

* feat: Introduce opening entry for reporting

(cherry picked from commit b44a19bd1a)

* fix: Add patches to create accounting dimension in Closing Balance

(cherry picked from commit 36c08d0835)

* feat: Cascade closing balances on PCV submit

(cherry picked from commit c3f39c3f32)

# Conflicts:
#	erpnext/accounts/doctype/period_closing_voucher/period_closing_voucher.py
#	erpnext/patches.txt

* feat: Add views in standard filter

(cherry picked from commit e18336ebe7)

* chore: Rewrite query using query builder

(cherry picked from commit 7fa7d6b5e4)

# Conflicts:
#	erpnext/accounts/doctype/period_closing_voucher/period_closing_voucher.py

* feat: Add validations against period closing voucher

(cherry picked from commit f92c63fb10)

* fix: Order by issue in aggregation query

(cherry picked from commit 6607c8bd82)

* fix: Add patch to update closing balances

(cherry picked from commit a663df376c)

* fix: Closing balance entries for period closing voucher

(cherry picked from commit 436fc03eda)

* fix: Update patch to generate closing balance entries

(cherry picked from commit 95c9aafda9)

# Conflicts:
#	erpnext/patches.txt

* perf: Apply closing balance in Trial Balance report

(cherry picked from commit e5f603c9d9)

# Conflicts:
#	erpnext/accounts/report/trial_balance/trial_balance.py

* chore: Minor fixes

(cherry picked from commit c089c4156c)

# Conflicts:
#	erpnext/patches.txt

* fix: Aggregation with previous closing balance

(cherry picked from commit 4a2046dfb6)

# Conflicts:
#	erpnext/patches.txt

* test: Add static posting dates to tests

(cherry picked from commit 310f71c313)

* chore: Add index to period closing voucher column

(cherry picked from commit 5dabc98ba5)

* chore: rename Closing Balance to Account Closing Balance

(cherry picked from commit 3249a79f07)

* test: Add test case for closing balance

(cherry picked from commit f0267feca8)

* chore: Use account closing balance in set gl entries

(cherry picked from commit 0157fa15eb)

# Conflicts:
#	erpnext/accounts/report/financial_statements.py

* fix: Update patch

(cherry picked from commit 76775a3e49)

* fix: Account sub query

(cherry picked from commit 7f11373b58)

* chore: Simplify query

(cherry picked from commit 00fe3042b2)

# Conflicts:
#	erpnext/accounts/doctype/period_closing_voucher/period_closing_voucher.py

* chore: Add missing validations

(cherry picked from commit 0aadb680eb)

* chore: Remove unnecessary list comprehension

(cherry picked from commit 44053db010)

# Conflicts:
#	erpnext/accounts/report/financial_statements.py

* fix: Ignore opening entries if PCV posted

(cherry picked from commit f9397a87ac)

# Conflicts:
#	erpnext/accounts/report/financial_statements.py

* fix: Don't validate if no GL Entry exists

(cherry picked from commit 528ab503f2)

* chore: Fix Typo

(cherry picked from commit 3fd95200da)

* fix: Validation for cancelation

(cherry picked from commit 30eb6c8512)

* fix: Partial trial balance view

(cherry picked from commit b7dcf27b01)

* fix: CS financial statement param

(cherry picked from commit f8cff09129)

* chore: Improve validation message

(cherry picked from commit 8ce1da111e)

* chore: Resolve conflicts

* chore: Resolve conflicts

---------

Co-authored-by: Deepesh Garg <deepeshgarg6@gmail.com>
This commit is contained in:
mergify[bot]
2023-07-10 18:04:45 +05:30
committed by GitHub
parent 16943ac248
commit ebf3c0173e
17 changed files with 988 additions and 182 deletions

View File

@@ -0,0 +1,8 @@
// Copyright (c) 2023, Frappe Technologies Pvt. Ltd. and contributors
// For license information, please see license.txt
// frappe.ui.form.on("Account Closing Balance", {
// refresh(frm) {
// },
// });

View File

@@ -0,0 +1,164 @@
{
"actions": [],
"creation": "2023-02-21 15:20:59.586811",
"default_view": "List",
"doctype": "DocType",
"document_type": "Document",
"engine": "InnoDB",
"field_order": [
"closing_date",
"account",
"cost_center",
"debit",
"credit",
"account_currency",
"debit_in_account_currency",
"credit_in_account_currency",
"project",
"company",
"finance_book",
"period_closing_voucher",
"is_period_closing_voucher_entry"
],
"fields": [
{
"fieldname": "closing_date",
"fieldtype": "Date",
"in_filter": 1,
"in_list_view": 1,
"label": "Closing Date",
"oldfieldname": "posting_date",
"oldfieldtype": "Date",
"search_index": 1
},
{
"fieldname": "account",
"fieldtype": "Link",
"in_filter": 1,
"in_list_view": 1,
"in_standard_filter": 1,
"label": "Account",
"oldfieldname": "account",
"oldfieldtype": "Link",
"options": "Account",
"search_index": 1
},
{
"fieldname": "cost_center",
"fieldtype": "Link",
"in_filter": 1,
"in_list_view": 1,
"label": "Cost Center",
"oldfieldname": "cost_center",
"oldfieldtype": "Link",
"options": "Cost Center"
},
{
"fieldname": "debit",
"fieldtype": "Currency",
"label": "Debit Amount",
"oldfieldname": "debit",
"oldfieldtype": "Currency",
"options": "Company:company:default_currency"
},
{
"fieldname": "credit",
"fieldtype": "Currency",
"label": "Credit Amount",
"oldfieldname": "credit",
"oldfieldtype": "Currency",
"options": "Company:company:default_currency"
},
{
"fieldname": "account_currency",
"fieldtype": "Link",
"label": "Account Currency",
"options": "Currency"
},
{
"fieldname": "debit_in_account_currency",
"fieldtype": "Currency",
"label": "Debit Amount in Account Currency",
"options": "account_currency"
},
{
"fieldname": "credit_in_account_currency",
"fieldtype": "Currency",
"label": "Credit Amount in Account Currency",
"options": "account_currency"
},
{
"fieldname": "project",
"fieldtype": "Link",
"label": "Project",
"options": "Project"
},
{
"fieldname": "company",
"fieldtype": "Link",
"in_filter": 1,
"in_list_view": 1,
"in_standard_filter": 1,
"label": "Company",
"oldfieldname": "company",
"oldfieldtype": "Link",
"options": "Company",
"search_index": 1
},
{
"fieldname": "finance_book",
"fieldtype": "Link",
"label": "Finance Book",
"options": "Finance Book"
},
{
"fieldname": "period_closing_voucher",
"fieldtype": "Link",
"in_standard_filter": 1,
"label": "Period Closing Voucher",
"options": "Period Closing Voucher",
"search_index": 1
},
{
"default": "0",
"fieldname": "is_period_closing_voucher_entry",
"fieldtype": "Check",
"label": "Is Period Closing Voucher Entry"
}
],
"icon": "fa fa-list",
"in_create": 1,
"links": [],
"modified": "2023-03-06 08:56:36.393237",
"modified_by": "Administrator",
"module": "Accounts",
"name": "Account Closing Balance",
"owner": "Administrator",
"permissions": [
{
"email": 1,
"export": 1,
"print": 1,
"read": 1,
"report": 1,
"role": "Accounts User"
},
{
"email": 1,
"export": 1,
"print": 1,
"read": 1,
"report": 1,
"role": "Accounts Manager"
},
{
"export": 1,
"read": 1,
"report": 1,
"role": "Auditor"
}
],
"sort_field": "modified",
"sort_order": "DESC",
"states": []
}

View File

@@ -0,0 +1,127 @@
# Copyright (c) 2023, Frappe Technologies Pvt. Ltd. and contributors
# For license information, please see license.txt
import frappe
from frappe.model.document import Document
from frappe.utils import cint, cstr
from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import (
get_accounting_dimensions,
)
class AccountClosingBalance(Document):
pass
def make_closing_entries(closing_entries, voucher_name):
accounting_dimensions = get_accounting_dimensions()
company = closing_entries[0].get("company")
closing_date = closing_entries[0].get("closing_date")
previous_closing_entries = get_previous_closing_entries(
company, closing_date, accounting_dimensions
)
combined_entries = closing_entries + previous_closing_entries
merged_entries = aggregate_with_last_account_closing_balance(
combined_entries, accounting_dimensions
)
for key, value in merged_entries.items():
cle = frappe.new_doc("Account Closing Balance")
cle.update(value)
cle.update(value["dimensions"])
cle.update(
{
"period_closing_voucher": voucher_name,
"closing_date": closing_date,
}
)
cle.submit()
def aggregate_with_last_account_closing_balance(entries, accounting_dimensions):
merged_entries = {}
for entry in entries:
key, key_values = generate_key(entry, accounting_dimensions)
merged_entries.setdefault(
key,
{
"debit": 0,
"credit": 0,
"debit_in_account_currency": 0,
"credit_in_account_currency": 0,
},
)
merged_entries[key]["dimensions"] = key_values
merged_entries[key]["debit"] += entry.get("debit")
merged_entries[key]["credit"] += entry.get("credit")
merged_entries[key]["debit_in_account_currency"] += entry.get("debit_in_account_currency")
merged_entries[key]["credit_in_account_currency"] += entry.get("credit_in_account_currency")
return merged_entries
def generate_key(entry, accounting_dimensions):
key = [
cstr(entry.get("account")),
cstr(entry.get("account_currency")),
cstr(entry.get("cost_center")),
cstr(entry.get("project")),
cstr(entry.get("finance_book")),
cint(entry.get("is_period_closing_voucher_entry")),
]
key_values = {
"company": cstr(entry.get("company")),
"account": cstr(entry.get("account")),
"account_currency": cstr(entry.get("account_currency")),
"cost_center": cstr(entry.get("cost_center")),
"project": cstr(entry.get("project")),
"finance_book": cstr(entry.get("finance_book")),
"is_period_closing_voucher_entry": cint(entry.get("is_period_closing_voucher_entry")),
}
for dimension in accounting_dimensions:
key.append(cstr(entry.get(dimension)))
key_values[dimension] = cstr(entry.get(dimension))
return tuple(key), key_values
def get_previous_closing_entries(company, closing_date, accounting_dimensions):
entries = []
last_period_closing_voucher = frappe.db.get_all(
"Period Closing Voucher",
filters={"docstatus": 1, "company": company, "posting_date": ("<", closing_date)},
fields=["name"],
order_by="posting_date desc",
limit=1,
)
if last_period_closing_voucher:
account_closing_balance = frappe.qb.DocType("Account Closing Balance")
query = frappe.qb.from_(account_closing_balance).select(
account_closing_balance.company,
account_closing_balance.account,
account_closing_balance.account_currency,
account_closing_balance.debit,
account_closing_balance.credit,
account_closing_balance.debit_in_account_currency,
account_closing_balance.credit_in_account_currency,
account_closing_balance.cost_center,
account_closing_balance.project,
account_closing_balance.finance_book,
account_closing_balance.is_period_closing_voucher_entry,
)
for dimension in accounting_dimensions:
query = query.select(account_closing_balance[dimension])
query = query.where(
account_closing_balance.period_closing_voucher == last_period_closing_voucher[0].name
)
entries = query.run(as_dict=1)
return entries

View File

@@ -0,0 +1,9 @@
# Copyright (c) 2023, Frappe Technologies Pvt. Ltd. and Contributors
# See license.txt
# import frappe
from frappe.tests.utils import FrappeTestCase
class TestAccountClosingBalance(FrappeTestCase):
pass

View File

@@ -4,12 +4,13 @@
import frappe import frappe
from frappe import _ from frappe import _
from frappe.utils import flt from frappe.query_builder.functions import Sum
from frappe.utils import add_days, flt
from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import ( from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import (
get_accounting_dimensions, get_accounting_dimensions,
) )
from erpnext.accounts.utils import get_account_currency from erpnext.accounts.utils import get_account_currency, get_fiscal_year, validate_fiscal_year
from erpnext.controllers.accounts_controller import AccountsController from erpnext.controllers.accounts_controller import AccountsController
@@ -20,9 +21,17 @@ class PeriodClosingVoucher(AccountsController):
def on_submit(self): def on_submit(self):
self.db_set("gle_processing_status", "In Progress") self.db_set("gle_processing_status", "In Progress")
self.make_gl_entries() get_opening_entries = False
if not frappe.db.exists(
"Period Closing Voucher", {"company": self.company, "docstatus": 1, "name": ("!=", self.name)}
):
get_opening_entries = True
self.make_gl_entries(get_opening_entries=get_opening_entries)
def on_cancel(self): def on_cancel(self):
self.validate_future_closing_vouchers()
self.db_set("gle_processing_status", "In Progress") self.db_set("gle_processing_status", "In Progress")
self.ignore_linked_doctypes = ("GL Entry", "Stock Ledger Entry") self.ignore_linked_doctypes = ("GL Entry", "Stock Ledger Entry")
gle_count = frappe.db.count( gle_count = frappe.db.count(
@@ -43,8 +52,27 @@ class PeriodClosingVoucher(AccountsController):
else: else:
make_reverse_gl_entries(voucher_type="Period Closing Voucher", voucher_no=self.name) make_reverse_gl_entries(voucher_type="Period Closing Voucher", voucher_no=self.name)
self.delete_closing_entries()
def validate_future_closing_vouchers(self):
if frappe.db.exists(
"Period Closing Voucher",
{"posting_date": (">", self.posting_date), "docstatus": 1, "company": self.company},
):
frappe.throw(
_(
"You can not cancel this Period Closing Voucher, please cancel the future Period Closing Vouchers first"
)
)
def delete_closing_entries(self):
closing_balance = frappe.qb.DocType("Account Closing Balance")
frappe.qb.from_(closing_balance).delete().where(
closing_balance.period_closing_voucher == self.name
).run()
def validate_account_head(self): def validate_account_head(self):
closing_account_type = frappe.db.get_value("Account", self.closing_account_head, "root_type") closing_account_type = frappe.get_cached_value("Account", self.closing_account_head, "root_type")
if closing_account_type not in ["Liability", "Equity"]: if closing_account_type not in ["Liability", "Equity"]:
frappe.throw( frappe.throw(
@@ -57,8 +85,6 @@ class PeriodClosingVoucher(AccountsController):
frappe.throw(_("Currency of the Closing Account must be {0}").format(company_currency)) frappe.throw(_("Currency of the Closing Account must be {0}").format(company_currency))
def validate_posting_date(self): def validate_posting_date(self):
from erpnext.accounts.utils import get_fiscal_year, validate_fiscal_year
validate_fiscal_year( validate_fiscal_year(
self.posting_date, self.fiscal_year, self.company, label=_("Posting Date"), doc=self self.posting_date, self.fiscal_year, self.company, label=_("Posting Date"), doc=self
) )
@@ -67,6 +93,8 @@ class PeriodClosingVoucher(AccountsController):
self.posting_date, self.fiscal_year, company=self.company self.posting_date, self.fiscal_year, company=self.company
)[1] )[1]
self.check_if_previous_year_closed()
pce = frappe.db.sql( pce = frappe.db.sql(
"""select name from `tabPeriod Closing Voucher` """select name from `tabPeriod Closing Voucher`
where posting_date > %s and fiscal_year = %s and docstatus = 1 and company = %s""", where posting_date > %s and fiscal_year = %s and docstatus = 1 and company = %s""",
@@ -79,28 +107,64 @@ class PeriodClosingVoucher(AccountsController):
) )
) )
def make_gl_entries(self): def check_if_previous_year_closed(self):
last_year_closing = add_days(self.year_start_date, -1)
previous_fiscal_year = get_fiscal_year(last_year_closing, company=self.company, boolean=True)
if previous_fiscal_year and not frappe.db.exists(
"GL Entry", {"posting_date": ("<=", last_year_closing), "company": self.company}
):
return
if previous_fiscal_year and not frappe.db.exists(
"Period Closing Voucher",
{"posting_date": ("<=", last_year_closing), "docstatus": 1, "company": self.company},
):
frappe.throw(_("Previous Year is not closed, please close it first"))
def make_gl_entries(self, get_opening_entries=False):
gl_entries = self.get_gl_entries() gl_entries = self.get_gl_entries()
closing_entries = self.get_grouped_gl_entries(get_opening_entries=get_opening_entries)
if gl_entries: if gl_entries:
if len(gl_entries) > 5000: if len(gl_entries) > 5000:
frappe.enqueue(process_gl_entries, gl_entries=gl_entries, queue="long") frappe.enqueue(
process_gl_entries,
gl_entries=gl_entries,
closing_entries=closing_entries,
voucher_name=self.name,
queue="long",
)
frappe.msgprint( frappe.msgprint(
_("The GL Entries will be processed in the background, it can take a few minutes."), _("The GL Entries will be processed in the background, it can take a few minutes."),
alert=True, alert=True,
) )
else: else:
process_gl_entries(gl_entries) process_gl_entries(gl_entries, closing_entries, voucher_name=self.name)
def get_grouped_gl_entries(self, get_opening_entries=False):
closing_entries = []
for acc in self.get_balances_based_on_dimensions(
group_by_account=True, for_aggregation=True, get_opening_entries=get_opening_entries
):
closing_entries.append(self.get_closing_entries(acc))
return closing_entries
def get_gl_entries(self): def get_gl_entries(self):
gl_entries = [] gl_entries = []
# pl account # pl account
for acc in self.get_pl_balances_based_on_dimensions(group_by_account=True): for acc in self.get_balances_based_on_dimensions(
group_by_account=True, report_type="Profit and Loss"
):
if flt(acc.bal_in_company_currency): if flt(acc.bal_in_company_currency):
gl_entries.append(self.get_gle_for_pl_account(acc)) gl_entries.append(self.get_gle_for_pl_account(acc))
# closing liability account # closing liability account
for acc in self.get_pl_balances_based_on_dimensions(group_by_account=False): for acc in self.get_balances_based_on_dimensions(
group_by_account=False, report_type="Profit and Loss"
):
if flt(acc.bal_in_company_currency): if flt(acc.bal_in_company_currency):
gl_entries.append(self.get_gle_for_closing_account(acc)) gl_entries.append(self.get_gle_for_closing_account(acc))
@@ -109,6 +173,8 @@ class PeriodClosingVoucher(AccountsController):
def get_gle_for_pl_account(self, acc): def get_gle_for_pl_account(self, acc):
gl_entry = self.get_gl_dict( gl_entry = self.get_gl_dict(
{ {
"company": self.company,
"closing_date": self.posting_date,
"account": acc.account, "account": acc.account,
"cost_center": acc.cost_center, "cost_center": acc.cost_center,
"finance_book": acc.finance_book, "finance_book": acc.finance_book,
@@ -121,6 +187,7 @@ class PeriodClosingVoucher(AccountsController):
if flt(acc.bal_in_account_currency) > 0 if flt(acc.bal_in_account_currency) > 0
else 0, else 0,
"credit": abs(flt(acc.bal_in_company_currency)) if flt(acc.bal_in_company_currency) > 0 else 0, "credit": abs(flt(acc.bal_in_company_currency)) if flt(acc.bal_in_company_currency) > 0 else 0,
"is_period_closing_voucher_entry": 1,
}, },
item=acc, item=acc,
) )
@@ -130,6 +197,8 @@ class PeriodClosingVoucher(AccountsController):
def get_gle_for_closing_account(self, acc): def get_gle_for_closing_account(self, acc):
gl_entry = self.get_gl_dict( gl_entry = self.get_gl_dict(
{ {
"company": self.company,
"closing_date": self.posting_date,
"account": self.closing_account_head, "account": self.closing_account_head,
"cost_center": acc.cost_center, "cost_center": acc.cost_center,
"finance_book": acc.finance_book, "finance_book": acc.finance_book,
@@ -142,12 +211,36 @@ class PeriodClosingVoucher(AccountsController):
if flt(acc.bal_in_account_currency) < 0 if flt(acc.bal_in_account_currency) < 0
else 0, else 0,
"credit": abs(flt(acc.bal_in_company_currency)) if flt(acc.bal_in_company_currency) < 0 else 0, "credit": abs(flt(acc.bal_in_company_currency)) if flt(acc.bal_in_company_currency) < 0 else 0,
"is_period_closing_voucher_entry": 1,
}, },
item=acc, item=acc,
) )
self.update_default_dimensions(gl_entry, acc) self.update_default_dimensions(gl_entry, acc)
return gl_entry return gl_entry
def get_closing_entries(self, acc):
closing_entry = self.get_gl_dict(
{
"company": self.company,
"closing_date": self.posting_date,
"period_closing_voucher": self.name,
"account": acc.account,
"cost_center": acc.cost_center,
"finance_book": acc.finance_book,
"account_currency": acc.account_currency,
"debit_in_account_currency": flt(acc.debit_in_account_currency),
"debit": flt(acc.debit),
"credit_in_account_currency": flt(acc.credit_in_account_currency),
"credit": flt(acc.credit),
},
item=acc,
)
for dimension in self.accounting_dimensions:
closing_entry.update({dimension: acc.get(dimension)})
return closing_entry
def update_default_dimensions(self, gl_entry, acc): def update_default_dimensions(self, gl_entry, acc):
if not self.accounting_dimensions: if not self.accounting_dimensions:
self.accounting_dimensions = get_accounting_dimensions() self.accounting_dimensions = get_accounting_dimensions()
@@ -155,44 +248,88 @@ class PeriodClosingVoucher(AccountsController):
for dimension in self.accounting_dimensions: for dimension in self.accounting_dimensions:
gl_entry.update({dimension: acc.get(dimension)}) gl_entry.update({dimension: acc.get(dimension)})
def get_pl_balances_based_on_dimensions(self, group_by_account=False): def get_balances_based_on_dimensions(
self, group_by_account=False, report_type=None, for_aggregation=False, get_opening_entries=False
):
"""Get balance for dimension-wise pl accounts""" """Get balance for dimension-wise pl accounts"""
dimension_fields = ["t1.cost_center", "t1.finance_book"] qb_dimension_fields = ["cost_center", "finance_book", "project"]
self.accounting_dimensions = get_accounting_dimensions() self.accounting_dimensions = get_accounting_dimensions()
for dimension in self.accounting_dimensions: for dimension in self.accounting_dimensions:
dimension_fields.append("t1.{0}".format(dimension)) qb_dimension_fields.append(dimension)
if group_by_account: if group_by_account:
dimension_fields.append("t1.account") qb_dimension_fields.append("account")
return frappe.db.sql( account_filters = {
""" "company": self.company,
select "is_group": 0,
t1.account_currency, }
{dimension_fields},
sum(t1.debit_in_account_currency) - sum(t1.credit_in_account_currency) as bal_in_account_currency, if report_type:
sum(t1.debit) - sum(t1.credit) as bal_in_company_currency account_filters.update({"report_type": report_type})
from `tabGL Entry` t1
where accounts = frappe.get_all("Account", filters=account_filters, pluck="name")
t1.is_cancelled = 0
and t1.account in (select name from `tabAccount` where report_type = 'Profit and Loss' and docstatus < 2 and company = %s) gl_entry = frappe.qb.DocType("GL Entry")
and t1.posting_date between %s and %s query = frappe.qb.from_(gl_entry).select(gl_entry.account, gl_entry.account_currency)
group by {dimension_fields}
""".format( if not for_aggregation:
dimension_fields=", ".join(dimension_fields), query = query.select(
(Sum(gl_entry.debit_in_account_currency) - Sum(gl_entry.credit_in_account_currency)).as_(
"bal_in_account_currency"
), ),
(self.company, self.get("year_start_date"), self.posting_date), (Sum(gl_entry.debit) - Sum(gl_entry.credit)).as_("bal_in_company_currency"),
as_dict=1, )
else:
query = query.select(
(Sum(gl_entry.debit_in_account_currency)).as_("debit_in_account_currency"),
(Sum(gl_entry.credit_in_account_currency)).as_("credit_in_account_currency"),
(Sum(gl_entry.debit)).as_("debit"),
(Sum(gl_entry.credit)).as_("credit"),
) )
for dimension in qb_dimension_fields:
query = query.select(gl_entry[dimension])
def process_gl_entries(gl_entries): query = query.where(
(gl_entry.company == self.company)
& (gl_entry.is_cancelled == 0)
& (gl_entry.account.isin(accounts))
)
if get_opening_entries:
query = query.where(
gl_entry.posting_date.between(self.get("year_start_date"), self.posting_date)
| gl_entry.is_opening
== "Yes"
)
else:
query = query.where(
gl_entry.posting_date.between(self.get("year_start_date"), self.posting_date)
& gl_entry.is_opening
== "No"
)
if for_aggregation:
query = query.where(gl_entry.voucher_type != "Period Closing Voucher")
for dimension in qb_dimension_fields:
query = query.groupby(gl_entry[dimension])
return query.run(as_dict=1)
def process_gl_entries(gl_entries, closing_entries, voucher_name=None):
from erpnext.accounts.doctype.account_closing_balance.account_closing_balance import (
make_closing_entries,
)
from erpnext.accounts.general_ledger import make_gl_entries from erpnext.accounts.general_ledger import make_gl_entries
try: try:
make_gl_entries(gl_entries, merge_entries=False) make_gl_entries(gl_entries, merge_entries=False)
make_closing_entries(gl_entries + closing_entries, voucher_name=voucher_name)
frappe.db.set_value( frappe.db.set_value(
"Period Closing Voucher", gl_entries[0].get("voucher_no"), "gle_processing_status", "Completed" "Period Closing Voucher", gl_entries[0].get("voucher_no"), "gle_processing_status", "Completed"
) )

View File

@@ -16,16 +16,17 @@ from erpnext.accounts.utils import get_fiscal_year, now
class TestPeriodClosingVoucher(unittest.TestCase): class TestPeriodClosingVoucher(unittest.TestCase):
def test_closing_entry(self): def test_closing_entry(self):
frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'") frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'")
frappe.db.sql("delete from `tabPeriod Closing Voucher` where company='Test PCV Company'")
company = create_company() company = create_company()
cost_center = create_cost_center("Test Cost Center 1") cost_center = create_cost_center("Test Cost Center 1")
jv1 = make_journal_entry( jv1 = make_journal_entry(
posting_date="2021-03-15",
amount=400, amount=400,
account1="Cash - TPC", account1="Cash - TPC",
account2="Sales - TPC", account2="Sales - TPC",
cost_center=cost_center, cost_center=cost_center,
posting_date=now(),
save=False, save=False,
) )
jv1.company = company jv1.company = company
@@ -33,18 +34,18 @@ class TestPeriodClosingVoucher(unittest.TestCase):
jv1.submit() jv1.submit()
jv2 = make_journal_entry( jv2 = make_journal_entry(
posting_date="2021-03-15",
amount=600, amount=600,
account1="Cost of Goods Sold - TPC", account1="Cost of Goods Sold - TPC",
account2="Cash - TPC", account2="Cash - TPC",
cost_center=cost_center, cost_center=cost_center,
posting_date=now(),
save=False, save=False,
) )
jv2.company = company jv2.company = company
jv2.save() jv2.save()
jv2.submit() jv2.submit()
pcv = self.make_period_closing_voucher() pcv = self.make_period_closing_voucher(posting_date="2021-03-31")
surplus_account = pcv.closing_account_head surplus_account = pcv.closing_account_head
expected_gle = ( expected_gle = (
@@ -65,6 +66,7 @@ class TestPeriodClosingVoucher(unittest.TestCase):
def test_cost_center_wise_posting(self): def test_cost_center_wise_posting(self):
frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'") frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'")
frappe.db.sql("delete from `tabPeriod Closing Voucher` where company='Test PCV Company'")
company = create_company() company = create_company()
surplus_account = create_account() surplus_account = create_account()
@@ -81,6 +83,7 @@ class TestPeriodClosingVoucher(unittest.TestCase):
debit_to="Debtors - TPC", debit_to="Debtors - TPC",
currency="USD", currency="USD",
customer="_Test Customer USD", customer="_Test Customer USD",
posting_date="2021-03-15",
) )
create_sales_invoice( create_sales_invoice(
company=company, company=company,
@@ -91,9 +94,10 @@ class TestPeriodClosingVoucher(unittest.TestCase):
debit_to="Debtors - TPC", debit_to="Debtors - TPC",
currency="USD", currency="USD",
customer="_Test Customer USD", customer="_Test Customer USD",
posting_date="2021-03-15",
) )
pcv = self.make_period_closing_voucher(submit=False) pcv = self.make_period_closing_voucher(posting_date="2021-03-31", submit=False)
pcv.save() pcv.save()
pcv.submit() pcv.submit()
surplus_account = pcv.closing_account_head surplus_account = pcv.closing_account_head
@@ -128,12 +132,13 @@ class TestPeriodClosingVoucher(unittest.TestCase):
def test_period_closing_with_finance_book_entries(self): def test_period_closing_with_finance_book_entries(self):
frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'") frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'")
frappe.db.sql("delete from `tabPeriod Closing Voucher` where company='Test PCV Company'")
company = create_company() company = create_company()
surplus_account = create_account() surplus_account = create_account()
cost_center = create_cost_center("Test Cost Center 1") cost_center = create_cost_center("Test Cost Center 1")
si = create_sales_invoice( create_sales_invoice(
company=company, company=company,
income_account="Sales - TPC", income_account="Sales - TPC",
expense_account="Cost of Goods Sold - TPC", expense_account="Cost of Goods Sold - TPC",
@@ -142,6 +147,7 @@ class TestPeriodClosingVoucher(unittest.TestCase):
debit_to="Debtors - TPC", debit_to="Debtors - TPC",
currency="USD", currency="USD",
customer="_Test Customer USD", customer="_Test Customer USD",
posting_date="2021-03-15",
) )
jv = make_journal_entry( jv = make_journal_entry(
@@ -149,14 +155,14 @@ class TestPeriodClosingVoucher(unittest.TestCase):
account2="Sales - TPC", account2="Sales - TPC",
amount=400, amount=400,
cost_center=cost_center, cost_center=cost_center,
posting_date=now(), posting_date="2021-03-15",
) )
jv.company = company jv.company = company
jv.finance_book = create_finance_book().name jv.finance_book = create_finance_book().name
jv.save() jv.save()
jv.submit() jv.submit()
pcv = self.make_period_closing_voucher() pcv = self.make_period_closing_voucher(posting_date="2021-03-31")
surplus_account = pcv.closing_account_head surplus_account = pcv.closing_account_head
expected_gle = ( expected_gle = (
@@ -194,14 +200,130 @@ class TestPeriodClosingVoucher(unittest.TestCase):
repost_doc.posting_date = add_months(today(), 13) repost_doc.posting_date = add_months(today(), 13)
repost_doc.save() repost_doc.save()
def make_period_closing_voucher(self, submit=True): def test_gl_entries_restrictions(self):
frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'")
frappe.db.sql("delete from `tabPeriod Closing Voucher` where company='Test PCV Company'")
company = create_company()
cost_center = create_cost_center("Test Cost Center 1")
self.make_period_closing_voucher(posting_date="2021-03-31")
jv1 = make_journal_entry(
posting_date="2021-03-15",
amount=400,
account1="Cash - TPC",
account2="Sales - TPC",
cost_center=cost_center,
save=False,
)
jv1.company = company
jv1.save()
self.assertRaises(frappe.ValidationError, jv1.submit)
def test_closing_balance_with_dimensions(self):
frappe.db.sql("delete from `tabGL Entry` where company='Test PCV Company'")
frappe.db.sql("delete from `tabPeriod Closing Voucher` where company='Test PCV Company'")
frappe.db.sql("delete from `tabAccount Closing Balance` where company='Test PCV Company'")
company = create_company()
cost_center1 = create_cost_center("Test Cost Center 1")
cost_center2 = create_cost_center("Test Cost Center 2")
jv1 = make_journal_entry(
posting_date="2021-03-15",
amount=400,
account1="Cash - TPC",
account2="Sales - TPC",
cost_center=cost_center1,
save=False,
)
jv1.company = company
jv1.save()
jv1.submit()
jv2 = make_journal_entry(
posting_date="2021-03-15",
amount=200,
account1="Cash - TPC",
account2="Sales - TPC",
cost_center=cost_center2,
save=False,
)
jv2.company = company
jv2.save()
jv2.submit()
pcv1 = self.make_period_closing_voucher(posting_date="2021-03-31")
closing_balance = frappe.db.get_value(
"Account Closing Balance",
{
"account": "Sales - TPC",
"cost_center": cost_center1,
"period_closing_voucher": pcv1.name,
"is_period_closing_voucher_entry": 0,
},
["credit", "credit_in_account_currency"],
as_dict=1,
)
self.assertEqual(closing_balance.credit, 400)
self.assertEqual(closing_balance.credit_in_account_currency, 400)
jv3 = make_journal_entry(
posting_date="2022-03-15",
amount=300,
account1="Cash - TPC",
account2="Sales - TPC",
cost_center=cost_center2,
save=False,
)
jv3.company = company
jv3.save()
jv3.submit()
pcv2 = self.make_period_closing_voucher(posting_date="2022-03-31")
cc1_closing_balance = frappe.db.get_value(
"Account Closing Balance",
{
"account": "Sales - TPC",
"cost_center": cost_center1,
"period_closing_voucher": pcv2.name,
"is_period_closing_voucher_entry": 0,
},
["credit", "credit_in_account_currency"],
as_dict=1,
)
cc2_closing_balance = frappe.db.get_value(
"Account Closing Balance",
{
"account": "Sales - TPC",
"cost_center": cost_center2,
"period_closing_voucher": pcv2.name,
"is_period_closing_voucher_entry": 0,
},
["credit", "credit_in_account_currency"],
as_dict=1,
)
self.assertEqual(cc1_closing_balance.credit, 400)
self.assertEqual(cc1_closing_balance.credit_in_account_currency, 400)
self.assertEqual(cc2_closing_balance.credit, 500)
self.assertEqual(cc2_closing_balance.credit_in_account_currency, 500)
def make_period_closing_voucher(self, posting_date=None, submit=True):
surplus_account = create_account() surplus_account = create_account()
cost_center = create_cost_center("Test Cost Center 1") cost_center = create_cost_center("Test Cost Center 1")
pcv = frappe.get_doc( pcv = frappe.get_doc(
{ {
"doctype": "Period Closing Voucher", "doctype": "Period Closing Voucher",
"transaction_date": today(), "transaction_date": posting_date or today(),
"posting_date": today(), "posting_date": posting_date or today(),
"company": "Test PCV Company", "company": "Test PCV Company",
"fiscal_year": get_fiscal_year(today(), company="Test PCV Company")[0], "fiscal_year": get_fiscal_year(today(), company="Test PCV Company")[0],
"cost_center": cost_center, "cost_center": cost_center,

View File

@@ -300,6 +300,9 @@ def save_entries(gl_map, adv_adj, update_outstanding, from_repost=False):
if gl_map: if gl_map:
check_freezing_date(gl_map[0]["posting_date"], adv_adj) check_freezing_date(gl_map[0]["posting_date"], adv_adj)
is_opening = any(d.get("is_opening") == "Yes" for d in gl_map)
if gl_map[0]["voucher_type"] != "Period Closing Voucher":
validate_against_pcv(is_opening, gl_map[0]["posting_date"], gl_map[0]["company"])
for entry in gl_map: for entry in gl_map:
make_entry(entry, adv_adj, update_outstanding, from_repost) make_entry(entry, adv_adj, update_outstanding, from_repost)
@@ -521,6 +524,9 @@ def make_reverse_gl_entries(
) )
validate_accounting_period(gl_entries) validate_accounting_period(gl_entries)
check_freezing_date(gl_entries[0]["posting_date"], adv_adj) check_freezing_date(gl_entries[0]["posting_date"], adv_adj)
is_opening = any(d.get("is_opening") == "Yes" for d in gl_entries)
validate_against_pcv(is_opening, gl_entries[0]["posting_date"], gl_entries[0]["company"])
set_as_cancel(gl_entries[0]["voucher_type"], gl_entries[0]["voucher_no"]) set_as_cancel(gl_entries[0]["voucher_type"], gl_entries[0]["voucher_no"])
for entry in gl_entries: for entry in gl_entries:
@@ -568,6 +574,28 @@ def check_freezing_date(posting_date, adv_adj=False):
) )
def validate_against_pcv(is_opening, posting_date, company):
if is_opening and frappe.db.exists(
"Period Closing Voucher", {"docstatus": 1, "company": company}
):
frappe.throw(
_("Opening Entry can not be created after Period Closing Voucher is created."),
title=_("Invalid Opening Entry"),
)
last_pcv_date = frappe.db.get_value(
"Period Closing Voucher", {"docstatus": 1, "company": company}, "max(posting_date)"
)
if last_pcv_date and getdate(posting_date) <= getdate(last_pcv_date):
message = _("Books have been closed till the period ending on {0}").format(
formatdate(last_pcv_date)
)
message += "</br >"
message += _("You cannot create/amend any accounting entries till this date.")
frappe.throw(message, title=_("Period Closed"))
def set_as_cancel(voucher_type, voucher_no): def set_as_cancel(voucher_type, voucher_no):
""" """
Set is_cancelled=1 in all original gl entries for the voucher Set is_cancelled=1 in all original gl entries for the voucher

View File

@@ -25,6 +25,8 @@ def execute(filters=None):
company=filters.company, company=filters.company,
) )
filters.period_start_date = period_list[0]["year_start_date"]
currency = filters.presentation_currency or frappe.get_cached_value( currency = filters.presentation_currency or frappe.get_cached_value(
"Company", filters.company, "default_currency" "Company", filters.company, "default_currency"
) )
@@ -96,7 +98,7 @@ def execute(filters=None):
chart = get_chart_data(filters, columns, asset, liability, equity) chart = get_chart_data(filters, columns, asset, liability, equity)
report_summary = get_report_summary( report_summary = get_report_summary(
period_list, asset, liability, equity, provisional_profit_loss, total_credit, currency, filters period_list, asset, liability, equity, provisional_profit_loss, currency, filters
) )
return columns, data, message, chart, report_summary return columns, data, message, chart, report_summary
@@ -174,7 +176,6 @@ def get_report_summary(
liability, liability,
equity, equity,
provisional_profit_loss, provisional_profit_loss,
total_credit,
currency, currency,
filters, filters,
consolidated=False, consolidated=False,

View File

@@ -118,7 +118,6 @@ def get_balance_sheet_data(fiscal_year, companies, columns, filters):
liability, liability,
equity, equity,
provisional_profit_loss, provisional_profit_loss,
total_credit,
company_currency, company_currency,
filters, filters,
True, True,

View File

@@ -418,50 +418,51 @@ def set_gl_entries_by_account(
ignore_closing_entries=False, ignore_closing_entries=False,
): ):
"""Returns a dict like { "account": [gl entries], ... }""" """Returns a dict like { "account": [gl entries], ... }"""
gl_entries = []
additional_conditions = get_additional_conditions(from_date, ignore_closing_entries, filters) accounts_list = frappe.db.get_all(
"Account",
accounts = frappe.db.sql_list( filters={"company": company, "is_group": 0, "lft": (">=", root_lft), "rgt": ("<=", root_rgt)},
"""select name from `tabAccount` pluck="name",
where lft >= %s and rgt <= %s and company = %s""",
(root_lft, root_rgt, company),
) )
if accounts: ignore_opening_entries = False
additional_conditions += " and account in ({})".format( if accounts_list:
", ".join(frappe.db.escape(d) for d in accounts) # For balance sheet
if not from_date:
from_date = filters["period_start_date"]
last_period_closing_voucher = frappe.db.get_all(
"Period Closing Voucher",
filters={"docstatus": 1, "company": filters.company, "posting_date": ("<", from_date)},
fields=["posting_date", "name"],
order_by="posting_date desc",
limit=1,
) )
if last_period_closing_voucher:
gl_entries += get_accounting_entries(
"Account Closing Balance",
from_date,
to_date,
accounts_list,
filters,
ignore_closing_entries,
last_period_closing_voucher[0].name,
)
from_date = add_days(last_period_closing_voucher[0].posting_date, 1)
ignore_opening_entries = True
gl_filters = { gl_entries += get_accounting_entries(
"company": company, "GL Entry",
"from_date": from_date, from_date,
"to_date": to_date, to_date,
"finance_book": cstr(filters.get("finance_book")), accounts_list,
} filters,
ignore_closing_entries,
if filters.get("include_default_book_entries"): ignore_opening_entries=ignore_opening_entries,
gl_filters["company_fb"] = frappe.db.get_value("Company", company, "default_finance_book")
for key, value in filters.items():
if value:
gl_filters.update({key: value})
gl_entries = frappe.db.sql(
"""
select posting_date, account, debit, credit, is_opening, fiscal_year,
debit_in_account_currency, credit_in_account_currency, account_currency from `tabGL Entry`
where company=%(company)s
{additional_conditions}
and posting_date <= %(to_date)s
and is_cancelled = 0""".format(
additional_conditions=additional_conditions
),
gl_filters,
as_dict=True,
) )
if filters and filters.get("presentation_currency"): if filters and filters.get("presentation_currency"):
convert_to_presentation_currency(gl_entries, get_currency(filters), filters.get("company")) convert_to_presentation_currency(gl_entries, get_currency(filters))
for entry in gl_entries: for entry in gl_entries:
gl_entries_by_account.setdefault(entry.account, []).append(entry) gl_entries_by_account.setdefault(entry.account, []).append(entry)
@@ -469,49 +470,90 @@ def set_gl_entries_by_account(
return gl_entries_by_account return gl_entries_by_account
def get_additional_conditions(from_date, ignore_closing_entries, filters): def get_accounting_entries(
additional_conditions = [] doctype,
from_date,
to_date,
accounts,
filters,
ignore_closing_entries,
period_closing_voucher=None,
ignore_opening_entries=False,
):
gl_entry = frappe.qb.DocType(doctype)
query = (
frappe.qb.from_(gl_entry)
.select(
gl_entry.account,
gl_entry.debit,
gl_entry.credit,
gl_entry.debit_in_account_currency,
gl_entry.credit_in_account_currency,
gl_entry.account_currency,
)
.where(gl_entry.company == filters.company)
)
if doctype == "GL Entry":
query = query.select(gl_entry.posting_date, gl_entry.is_opening, gl_entry.fiscal_year)
query = query.where(gl_entry.is_cancelled == 0)
query = query.where(gl_entry.posting_date <= to_date)
if ignore_opening_entries:
query = query.where(gl_entry.is_opening == "No")
else:
query = query.select(gl_entry.closing_date.as_("posting_date"))
query = query.where(gl_entry.period_closing_voucher == period_closing_voucher)
query = apply_additional_conditions(doctype, query, from_date, ignore_closing_entries, filters)
query = query.where(gl_entry.account.isin(accounts))
entries = query.run(as_dict=True)
return entries
def apply_additional_conditions(doctype, query, from_date, ignore_closing_entries, filters):
gl_entry = frappe.qb.DocType(doctype)
accounting_dimensions = get_accounting_dimensions(as_list=False) accounting_dimensions = get_accounting_dimensions(as_list=False)
if ignore_closing_entries: if ignore_closing_entries:
additional_conditions.append("ifnull(voucher_type, '')!='Period Closing Voucher'") if doctype == "GL Entry":
query = query.where(gl_entry.voucher_type != "Period Closing Voucher")
else:
query = query.where(gl_entry.is_period_closing_voucher_entry == 0)
if from_date: if from_date and doctype == "GL Entry":
additional_conditions.append("posting_date >= %(from_date)s") query = query.where(gl_entry.posting_date >= from_date)
if filters: if filters:
if filters.get("project"): if filters.get("project"):
if not isinstance(filters.get("project"), list): if not isinstance(filters.get("project"), list):
filters.project = frappe.parse_json(filters.get("project")) filters.project = frappe.parse_json(filters.get("project"))
additional_conditions.append("project in %(project)s") query = query.where(gl_entry.project.isin(filters.project))
if filters.get("cost_center"): if filters.get("cost_center"):
filters.cost_center = get_cost_centers_with_children(filters.cost_center) filters.cost_center = get_cost_centers_with_children(filters.cost_center)
additional_conditions.append("cost_center in %(cost_center)s") query = query.where(gl_entry.cost_center.isin(filters.cost_center))
if filters.get("include_default_book_entries"): if filters.get("include_default_book_entries"):
if filters.get("finance_book"): company_fb = frappe.get_cached_value("Company", filters.company, "default_finance_book")
if filters.get("company_fb") and cstr(filters.get("finance_book")) != cstr(
filters.get("company_fb") if filters.finance_book and company_fb and cstr(filters.finance_book) != cstr(company_fb):
):
frappe.throw( frappe.throw(
_("To use a different finance book, please uncheck 'Include Default Book Entries'") _("To use a different finance book, please uncheck 'Include Default Book Entries'")
) )
else:
additional_conditions.append( query = query.where(
"(finance_book in (%(finance_book)s, '') OR finance_book IS NULL)" (gl_entry.finance_book.isin([cstr(filters.finance_book), cstr(company_fb), ""]))
| (gl_entry.finance_book.isnull())
) )
else: else:
additional_conditions.append("(finance_book in (%(company_fb)s, '') OR finance_book IS NULL)") query = query.where(
else: (gl_entry.finance_book.isin([cstr(filters.finance_book), ""]))
if filters.get("finance_book"): | (gl_entry.finance_book.isnull())
additional_conditions.append(
"(finance_book in (%(finance_book)s, '') OR finance_book IS NULL)"
) )
else:
additional_conditions.append("(finance_book in ('') OR finance_book IS NULL)")
if accounting_dimensions: if accounting_dimensions:
for dimension in accounting_dimensions: for dimension in accounting_dimensions:
@@ -520,11 +562,10 @@ def get_additional_conditions(from_date, ignore_closing_entries, filters):
filters[dimension.fieldname] = get_dimension_with_children( filters[dimension.fieldname] = get_dimension_with_children(
dimension.document_type, filters.get(dimension.fieldname) dimension.document_type, filters.get(dimension.fieldname)
) )
additional_conditions.append("{0} in %({0})s".format(dimension.fieldname))
else:
additional_conditions.append("{0} in %({0})s".format(dimension.fieldname))
return " and {}".format(" and ".join(additional_conditions)) if additional_conditions else "" query = query.where(gl_entry[dimension.fieldname].isin(filters[dimension.fieldname]))
return query
def get_cost_centers_with_children(cost_centers): def get_cost_centers_with_children(cost_centers):

View File

@@ -4,7 +4,8 @@
import frappe import frappe
from frappe import _ from frappe import _
from frappe.utils import cstr, flt, formatdate, getdate from frappe.query_builder.functions import Sum
from frappe.utils import add_days, cstr, flt, formatdate, getdate
import erpnext import erpnext
from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import ( from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import (
@@ -137,58 +138,127 @@ def get_opening_balances(filters):
def get_rootwise_opening_balances(filters, report_type): def get_rootwise_opening_balances(filters, report_type):
additional_conditions = "" gle = []
if not filters.show_unclosed_fy_pl_balances:
additional_conditions = ( last_period_closing_voucher = frappe.db.get_all(
" and posting_date >= %(year_start_date)s" if report_type == "Profit and Loss" else "" "Period Closing Voucher",
filters={"docstatus": 1, "company": filters.company, "posting_date": ("<", filters.from_date)},
fields=["posting_date", "name"],
order_by="posting_date desc",
limit=1,
) )
accounting_dimensions = get_accounting_dimensions(as_list=False)
if last_period_closing_voucher:
gle = get_opening_balance(
"Account Closing Balance",
filters,
report_type,
accounting_dimensions,
period_closing_voucher=last_period_closing_voucher[0].name,
)
if getdate(last_period_closing_voucher[0].posting_date) < getdate(
add_days(filters.from_date, -1)
):
start_date = add_days(last_period_closing_voucher[0].posting_date, 1)
gle += get_opening_balance(
"GL Entry", filters, report_type, accounting_dimensions, start_date=start_date
)
else:
gle = get_opening_balance("GL Entry", filters, report_type, accounting_dimensions)
opening = frappe._dict()
for d in gle:
opening.setdefault(
d.account,
{
"account": d.account,
"opening_debit": 0.0,
"opening_credit": 0.0,
},
)
opening[d.account]["opening_debit"] += flt(d.opening_debit)
opening[d.account]["opening_credit"] += flt(d.opening_credit)
return opening
def get_opening_balance(
doctype, filters, report_type, accounting_dimensions, period_closing_voucher=None, start_date=None
):
closing_balance = frappe.qb.DocType(doctype)
account = frappe.qb.DocType("Account")
opening_balance = (
frappe.qb.from_(closing_balance)
.select(
closing_balance.account,
Sum(closing_balance.debit).as_("opening_debit"),
Sum(closing_balance.credit).as_("opening_credit"),
)
.where(
(closing_balance.company == filters.company)
& (
closing_balance.account.isin(
frappe.qb.from_(account).select("name").where(account.report_type == report_type)
)
)
)
.groupby(closing_balance.account)
)
if period_closing_voucher:
opening_balance = opening_balance.where(
closing_balance.period_closing_voucher == period_closing_voucher
)
else:
if start_date:
opening_balance = opening_balance.where(closing_balance.posting_date >= start_date)
opening_balance = opening_balance.where(closing_balance.is_opening == "No")
opening_balance = opening_balance.where(closing_balance.posting_date < filters.from_date)
if (
not filters.show_unclosed_fy_pl_balances
and report_type == "Profit and Loss"
and doctype == "GL Entry"
):
opening_balance = opening_balance.where(closing_balance.posting_date >= filters.year_start_date)
if not flt(filters.with_period_closing_entry): if not flt(filters.with_period_closing_entry):
additional_conditions += " and ifnull(voucher_type, '')!='Period Closing Voucher'" if doctype == "Account Closing Balance":
opening_balance = opening_balance.where(closing_balance.is_period_closing_voucher_entry == 0)
else:
opening_balance = opening_balance.where(
closing_balance.voucher_type != "Period Closing Voucher"
)
if filters.cost_center: if filters.cost_center:
lft, rgt = frappe.db.get_value("Cost Center", filters.cost_center, ["lft", "rgt"]) lft, rgt = frappe.db.get_value("Cost Center", filters.cost_center, ["lft", "rgt"])
additional_conditions += """ and cost_center in (select name from `tabCost Center` cost_center = frappe.qb.DocType("Cost Center")
where lft >= %s and rgt <= %s)""" % ( opening_balance = opening_balance.where(
lft, closing_balance.cost_center.in_(
rgt, frappe.qb.from_(cost_center)
.select("name")
.where((cost_center.lft >= lft) & (cost_center.rgt <= rgt))
)
) )
if filters.project: if filters.project:
additional_conditions += " and project = %(project)s" opening_balance = opening_balance.where(closing_balance.project == filters.project)
company_fb = frappe.db.get_value("Company", filters.company, "default_finance_book") company_fb = frappe.db.get_value("Company", filters.company, "default_finance_book")
if filters.get("include_default_book_entries"): if filters.get("include_default_book_entries"):
if filters.get("finance_book"): opening_balance = opening_balance.where(
if company_fb and cstr(filters.get("finance_book")) != cstr(company_fb): (closing_balance.finance_book.isin([cstr(filters.finance_book), cstr(company_fb), ""]))
frappe.throw( | (closing_balance.finance_book.isnull())
_("To use a different finance book, please uncheck 'Include Default Book Entries'")
) )
else: else:
additional_conditions += ( opening_balance = opening_balance.where(
" AND (finance_book in (%(finance_book)s, '') OR finance_book IS NULL)" (closing_balance.finance_book.isin([cstr(filters.finance_book), ""]))
| (closing_balance.finance_book.isnull())
) )
else:
additional_conditions += " AND (finance_book in (%(company_fb)s, '') OR finance_book IS NULL)"
else:
if filters.get("finance_book"):
additional_conditions += " AND (finance_book in (%(finance_book)s, '') OR finance_book IS NULL)"
else:
additional_conditions += " AND (finance_book in ('') OR finance_book IS NULL)"
accounting_dimensions = get_accounting_dimensions(as_list=False)
query_filters = {
"company": filters.company,
"from_date": filters.from_date,
"to_date": filters.to_date,
"report_type": report_type,
"year_start_date": filters.year_start_date,
"project": filters.project,
"finance_book": filters.finance_book,
"company_fb": company_fb,
}
if accounting_dimensions: if accounting_dimensions:
for dimension in accounting_dimensions: for dimension in accounting_dimensions:
@@ -197,35 +267,17 @@ def get_rootwise_opening_balances(filters, report_type):
filters[dimension.fieldname] = get_dimension_with_children( filters[dimension.fieldname] = get_dimension_with_children(
dimension.document_type, filters.get(dimension.fieldname) dimension.document_type, filters.get(dimension.fieldname)
) )
additional_conditions += " and {0} in %({0})s".format(dimension.fieldname) opening_balance = opening_balance.where(
closing_balance[dimension.fieldname].isin(filters[dimension.fieldname])
)
else: else:
additional_conditions += " and {0} in %({0})s".format(dimension.fieldname) opening_balance = opening_balance.where(
closing_balance[dimension.fieldname].isin(filters[dimension.fieldname])
query_filters.update({dimension.fieldname: filters.get(dimension.fieldname)})
gle = frappe.db.sql(
"""
select
account, sum(debit) as opening_debit, sum(credit) as opening_credit
from `tabGL Entry`
where
company=%(company)s
{additional_conditions}
and (posting_date < %(from_date)s or (ifnull(is_opening, 'No') = 'Yes' and posting_date <= %(to_date)s))
and account in (select name from `tabAccount` where report_type=%(report_type)s)
and is_cancelled = 0
group by account""".format(
additional_conditions=additional_conditions
),
query_filters,
as_dict=True,
) )
opening = frappe._dict() gle = opening_balance.run(as_dict=1)
for d in gle:
opening.setdefault(d.account, d)
return opening return gle
def calculate_values(accounts, gl_entries_by_account, opening_balances): def calculate_values(accounts, gl_entries_by_account, opening_balances):

View File

@@ -51,13 +51,25 @@ GL_REPOSTING_CHUNK = 100
@frappe.whitelist() @frappe.whitelist()
def get_fiscal_year( def get_fiscal_year(
date=None, fiscal_year=None, label="Date", verbose=1, company=None, as_dict=False date=None, fiscal_year=None, label="Date", verbose=1, company=None, as_dict=False, boolean=False
): ):
return get_fiscal_years(date, fiscal_year, label, verbose, company, as_dict=as_dict)[0] fiscal_years = get_fiscal_years(
date, fiscal_year, label, verbose, company, as_dict=as_dict, boolean=boolean
)
if boolean:
return fiscal_years
else:
return fiscal_years[0]
def get_fiscal_years( def get_fiscal_years(
transaction_date=None, fiscal_year=None, label="Date", verbose=1, company=None, as_dict=False transaction_date=None,
fiscal_year=None,
label="Date",
verbose=1,
company=None,
as_dict=False,
boolean=False,
): ):
fiscal_years = frappe.cache().hget("fiscal_years", company) or [] fiscal_years = frappe.cache().hget("fiscal_years", company) or []
@@ -121,8 +133,12 @@ def get_fiscal_years(
if company: if company:
error_msg = _("""{0} for {1}""").format(error_msg, frappe.bold(company)) error_msg = _("""{0} for {1}""").format(error_msg, frappe.bold(company))
if boolean:
return False
if verbose == 1: if verbose == 1:
frappe.msgprint(error_msg) frappe.msgprint(error_msg)
raise FiscalYearError(error_msg) raise FiscalYearError(error_msg)

View File

@@ -527,6 +527,7 @@ accounting_dimension_doctypes = [
"Subcontracting Order Item", "Subcontracting Order Item",
"Subcontracting Receipt", "Subcontracting Receipt",
"Subcontracting Receipt Item", "Subcontracting Receipt Item",
"Account Closing Balance",
] ]
# get matching queries for Bank Reconciliation # get matching queries for Bank Reconciliation

View File

@@ -335,3 +335,5 @@ erpnext.patches.v14_0.set_packed_qty_in_draft_delivery_notes
erpnext.patches.v14_0.cleanup_workspaces erpnext.patches.v14_0.cleanup_workspaces
erpnext.patches.v14_0.enable_allow_existing_serial_no erpnext.patches.v14_0.enable_allow_existing_serial_no
erpnext.patches.v14_0.set_report_in_process_SOA erpnext.patches.v14_0.set_report_in_process_SOA
erpnext.patches.v14_0.create_accounting_dimensions_for_closing_balance
erpnext.patches.v14_0.update_closing_balances

View File

@@ -0,0 +1,31 @@
import frappe
from frappe.custom.doctype.custom_field.custom_field import create_custom_field
def execute():
accounting_dimensions = frappe.db.get_all(
"Accounting Dimension", fields=["fieldname", "label", "document_type", "disabled"]
)
if not accounting_dimensions:
return
doctype = "Account Closing Balance"
for d in accounting_dimensions:
field = frappe.db.get_value("Custom Field", {"dt": doctype, "fieldname": d.fieldname})
if field:
continue
df = {
"fieldname": d.fieldname,
"label": d.label,
"fieldtype": "Link",
"options": d.document_type,
"insert_after": "accounting_dimensions_section",
}
create_custom_field(doctype, df, ignore_validate=True)
frappe.clear_cache(doctype=doctype)

View File

@@ -0,0 +1,68 @@
# Copyright (c) 2023, Frappe Technologies Pvt. Ltd. and Contributors
# License: MIT. See LICENSE
import frappe
from erpnext.accounts.doctype.account_closing_balance.account_closing_balance import (
make_closing_entries,
)
from erpnext.accounts.utils import get_fiscal_year
def execute():
frappe.db.truncate("Account Closing Balance")
i = 0
company_wise_order = {}
for pcv in frappe.db.get_all(
"Period Closing Voucher",
fields=["company", "posting_date", "name"],
filters={"docstatus": 1},
order_by="posting_date",
):
company_wise_order.setdefault(pcv.company, [])
if pcv.posting_date not in company_wise_order[pcv.company]:
pcv_doc = frappe.get_doc("Period Closing Voucher", pcv.name)
pcv_doc.year_start_date = get_fiscal_year(
pcv.posting_date, pcv.fiscal_year, company=pcv.company
)[1]
# get gl entries against pcv
gl_entries = frappe.db.get_all(
"GL Entry", filters={"voucher_no": pcv.name, "is_cancelled": 0}, fields=["*"]
)
for entry in gl_entries:
entry["is_period_closing_voucher_entry"] = 1
entry["closing_date"] = pcv_doc.posting_date
entry["period_closing_voucher"] = pcv_doc.name
# get all gl entries for the year
closing_entries = frappe.db.get_all(
"GL Entry",
filters={
"is_cancelled": 0,
"voucher_no": ["!=", pcv.name],
"posting_date": ["between", [pcv_doc.year_start_date, pcv.posting_date]],
"is_opening": "No",
},
fields=["*"],
)
if i == 0:
# add opening entries only for the first pcv
closing_entries += frappe.db.get_all(
"GL Entry",
filters={"is_cancelled": 0, "is_opening": "Yes"},
fields=["*"],
)
for entry in closing_entries:
entry["closing_date"] = pcv_doc.posting_date
entry["period_closing_voucher"] = pcv_doc.name
make_closing_entries(gl_entries + closing_entries, voucher_name=pcv.name)
company_wise_order[pcv.company].append(pcv.posting_date)
i += 1