Merge pull request #48585 from frappe/mergify/bp/version-14-hotfix/pr-47892

refactor: use sql for building voucher balance in Receivable report (backport #47892)
This commit is contained in:
ruthra kumar
2025-07-15 08:23:20 +05:30
committed by GitHub
5 changed files with 268 additions and 9 deletions

View File

@@ -3,4 +3,14 @@
frappe.ui.form.on("Accounts Settings", {
refresh: function (frm) {},
drop_ar_procedures: function (frm) {
frm.call({
doc: frm.doc,
method: "drop_ar_sql_procedures",
callback: function (r) {
frappe.show_alert(__("Procedures dropped"), 5);
},
});
},
});

View File

@@ -77,6 +77,8 @@
"receivable_payable_remarks_length",
"accounts_receivable_payable_tuning_section",
"receivable_payable_fetch_method",
"column_break_ntmi",
"drop_ar_procedures",
"legacy_section",
"ignore_is_opening_check_for_reporting"
],
@@ -488,7 +490,7 @@
"fieldname": "receivable_payable_fetch_method",
"fieldtype": "Select",
"label": "Data Fetch Method",
"options": "Buffered Cursor\nUnBuffered Cursor"
"options": "Buffered Cursor\nUnBuffered Cursor\nRaw SQL"
},
{
"fieldname": "accounts_receivable_payable_tuning_section",
@@ -499,6 +501,17 @@
"fieldname": "legacy_section",
"fieldtype": "Section Break",
"label": "Legacy Fields"
},
{
"fieldname": "column_break_ntmi",
"fieldtype": "Column Break"
},
{
"depends_on": "eval:doc.receivable_payable_fetch_method == \"Raw SQL\"",
"description": "Drops existing SQL Procedures and Function setup by Accounts Receivable report",
"fieldname": "drop_ar_procedures",
"fieldtype": "Button",
"label": "Drop Procedures"
}
],
"icon": "icon-cog",

View File

@@ -65,3 +65,11 @@ class AccountsSettings(Document):
def validate_pending_reposts(self):
if self.acc_frozen_upto:
check_pending_reposting(self.acc_frozen_upto)
@frappe.whitelist()
def drop_ar_sql_procedures(self):
from erpnext.accounts.report.accounts_receivable.accounts_receivable import InitSQLProceduresForAR
frappe.db.sql(f"drop function if exists {InitSQLProceduresForAR.genkey_function_name}")
frappe.db.sql(f"drop procedure if exists {InitSQLProceduresForAR.init_procedure_name}")
frappe.db.sql(f"drop procedure if exists {InitSQLProceduresForAR.allocate_procedure_name}")

View File

@@ -6,6 +6,7 @@ from collections import OrderedDict
import frappe
from frappe import _, qb, query_builder, scrub
from frappe.database.schema import get_definition
from frappe.query_builder import Criterion
from frappe.query_builder.functions import Date, Substring, Sum
from frappe.utils import cint, cstr, flt, getdate, nowdate
@@ -14,7 +15,10 @@ from erpnext.accounts.doctype.accounting_dimension.accounting_dimension import (
get_accounting_dimensions,
get_dimension_with_children,
)
from erpnext.accounts.utils import get_currency_precision
from erpnext.accounts.utils import (
build_qb_match_conditions,
get_currency_precision,
)
# This report gives a summary of all Outstanding Invoices considering the following
@@ -91,9 +95,6 @@ class ReceivablePayableReport:
def get_data(self):
self.get_sales_invoices_or_customers_based_on_sales_person()
# Build delivery note map against all sales invoices
self.build_delivery_note_map()
# Get invoice details like bill_no, due_date etc for all invoices
self.get_invoice_details()
@@ -114,12 +115,16 @@ class ReceivablePayableReport:
self.fetch_ple_in_buffered_cursor()
elif self.ple_fetch_method == "UnBuffered Cursor":
self.fetch_ple_in_unbuffered_cursor()
elif self.ple_fetch_method == "Raw SQL":
self.fetch_ple_in_sql_procedures()
# Build delivery note map against all sales invoices
self.build_delivery_note_map()
self.build_data()
def fetch_ple_in_buffered_cursor(self):
query, param = self.ple_query.walk()
self.ple_entries = frappe.db.sql(query, param, as_dict=True)
self.ple_entries = self.ple_query.run(as_dict=True)
for ple in self.ple_entries:
self.init_voucher_balance(ple) # invoiced, paid, credit_note, outstanding
@@ -132,9 +137,8 @@ class ReceivablePayableReport:
def fetch_ple_in_unbuffered_cursor(self):
self.ple_entries = []
query, param = self.ple_query.walk()
with frappe.db.unbuffered_cursor():
for ple in frappe.db.sql(query, param, as_dict=True, as_iterator=True):
for ple in self.ple_query.run(as_dict=True, as_iterator=True):
self.init_voucher_balance(ple) # invoiced, paid, credit_note, outstanding
self.ple_entries.append(ple)
@@ -299,6 +303,79 @@ class ReceivablePayableReport:
row.paid -= amount
row.paid_in_account_currency -= amount_in_account_currency
def fetch_ple_in_sql_procedures(self):
self.proc = InitSQLProceduresForAR()
build_balance = f"""
begin not atomic
declare done boolean default false;
declare rec1 row type of `{self.proc._row_def_table_name}`;
declare ple cursor for {self.ple_query.get_sql()};
declare continue handler for not found set done = true;
open ple;
fetch ple into rec1;
while not done do
call {self.proc.init_procedure_name}(rec1);
fetch ple into rec1;
end while;
close ple;
set done = false;
open ple;
fetch ple into rec1;
while not done do
call {self.proc.allocate_procedure_name}(rec1);
fetch ple into rec1;
end while;
close ple;
end;
"""
frappe.db.sql(build_balance)
balances = frappe.db.sql(
f"""select
name,
voucher_type,
voucher_no,
party,
party_account `account`,
posting_date,
account_currency,
cost_center,
sum(invoiced) `invoiced`,
sum(paid) `paid`,
sum(credit_note) `credit_note`,
sum(invoiced) - sum(paid) - sum(credit_note) `outstanding`,
sum(invoiced_in_account_currency) `invoiced_in_account_currency`,
sum(paid_in_account_currency) `paid_in_account_currency`,
sum(credit_note_in_account_currency) `credit_note_in_account_currency`,
sum(invoiced_in_account_currency) - sum(paid_in_account_currency) - sum(credit_note_in_account_currency) `outstanding_in_account_currency`
from `{self.proc._voucher_balance_name}` group by name order by posting_date;""",
as_dict=True,
)
for x in balances:
if self.filters.get("ignore_accounts"):
key = (x.voucher_type, x.voucher_no, x.party)
else:
key = (x.account, x.voucher_type, x.voucher_no, x.party)
_d = self.build_voucher_dict(x)
for field in [
"invoiced",
"paid",
"credit_note",
"outstanding",
"invoiced_in_account_currency",
"paid_in_account_currency",
"credit_note_in_account_currency",
"outstanding_in_account_currency",
"cost_center",
]:
_d[field] = x.get(field)
self.voucher_balance[key] = _d
def update_sub_total_row(self, row, party):
total_row = self.total_row_map.get(party)
@@ -839,6 +916,9 @@ class ReceivablePayableReport:
else:
query = query.select(ple.remarks)
if match_conditions := build_qb_match_conditions("Payment Ledger Entry"):
query = query.where(Criterion.all(match_conditions))
if self.filters.get("group_by_party"):
query = query.orderby(self.ple.party, self.ple.posting_date)
else:
@@ -1231,3 +1311,134 @@ def get_customer_group_with_children(customer_groups):
frappe.throw(_("Customer Group: {0} does not exist").format(d))
return list(set(all_customer_groups))
class InitSQLProceduresForAR:
"""
Initialize SQL Procedures, Functions and Temporary tables to build Receivable / Payable report
"""
_varchar_type = get_definition("Data")
_currency_type = get_definition("Currency")
# Temporary Tables
_voucher_balance_name = "_ar_voucher_balance"
_voucher_balance_definition = f"""
create temporary table `{_voucher_balance_name}`(
name {_varchar_type},
voucher_type {_varchar_type},
voucher_no {_varchar_type},
party {_varchar_type},
party_account {_varchar_type},
posting_date date,
account_currency {_varchar_type},
cost_center {_varchar_type},
invoiced {_currency_type},
paid {_currency_type},
credit_note {_currency_type},
invoiced_in_account_currency {_currency_type},
paid_in_account_currency {_currency_type},
credit_note_in_account_currency {_currency_type}) engine=memory;
"""
_row_def_table_name = "_ar_ple_row"
_row_def_table_definition = f"""
create temporary table `{_row_def_table_name}`(
name {_varchar_type},
account {_varchar_type},
voucher_type {_varchar_type},
voucher_no {_varchar_type},
against_voucher_type {_varchar_type},
against_voucher_no {_varchar_type},
party_type {_varchar_type},
cost_center {_varchar_type},
party {_varchar_type},
posting_date date,
due_date date,
account_currency {_varchar_type},
amount {_currency_type},
amount_in_account_currency {_currency_type}) engine=memory;
"""
# Function
genkey_function_name = "ar_genkey"
genkey_function_sql = f"""
create function `{genkey_function_name}`(rec row type of `{_row_def_table_name}`, allocate bool) returns char(40)
begin
if allocate then
return sha1(concat_ws(',', rec.account, rec.against_voucher_type, rec.against_voucher_no, rec.party));
else
return sha1(concat_ws(',', rec.account, rec.voucher_type, rec.voucher_no, rec.party));
end if;
end
"""
# Procedures
init_procedure_name = "ar_init_tmp_table"
init_procedure_sql = f"""
create procedure ar_init_tmp_table(in ple row type of `{_row_def_table_name}`)
begin
if not exists (select name from `{_voucher_balance_name}` where name = `{genkey_function_name}`(ple, false))
then
insert into `{_voucher_balance_name}` values (`{genkey_function_name}`(ple, false), ple.voucher_type, ple.voucher_no, ple.party, ple.account, ple.posting_date, ple.account_currency, ple.cost_center, 0, 0, 0, 0, 0, 0);
end if;
end;
"""
allocate_procedure_name = "ar_allocate_to_tmp_table"
allocate_procedure_sql = f"""
create procedure ar_allocate_to_tmp_table(in ple row type of `{_row_def_table_name}`)
begin
declare invoiced {_currency_type} default 0;
declare invoiced_in_account_currency {_currency_type} default 0;
declare paid {_currency_type} default 0;
declare paid_in_account_currency {_currency_type} default 0;
declare credit_note {_currency_type} default 0;
declare credit_note_in_account_currency {_currency_type} default 0;
if ple.amount > 0 then
if (ple.voucher_type in ("Journal Entry", "Payment Entry") and (ple.voucher_no != ple.against_voucher_no)) then
set paid = -1 * ple.amount;
set paid_in_account_currency = -1 * ple.amount_in_account_currency;
else
set invoiced = ple.amount;
set invoiced_in_account_currency = ple.amount_in_account_currency;
end if;
else
if ple.voucher_type in ("Sales Invoice", "Purchase Invoice") then
if (ple.voucher_no = ple.against_voucher_no) then
set paid = -1 * ple.amount;
set paid_in_account_currency = -1 * ple.amount_in_account_currency;
else
set credit_note = -1 * ple.amount;
set credit_note_in_account_currency = -1 * ple.amount_in_account_currency;
end if;
else
set paid = -1 * ple.amount;
set paid_in_account_currency = -1 * ple.amount_in_account_currency;
end if;
end if;
insert into `{_voucher_balance_name}` values (`{genkey_function_name}`(ple, true), ple.against_voucher_type, ple.against_voucher_no, ple.party, ple.account, ple.posting_date, ple.account_currency,'', invoiced, paid, 0, invoiced_in_account_currency, paid_in_account_currency, 0);
end;
"""
def __init__(self):
existing_procedures = frappe.db.get_routines()
if self.genkey_function_name not in existing_procedures:
frappe.db.sql(self.genkey_function_sql)
if self.init_procedure_name not in existing_procedures:
frappe.db.sql(self.init_procedure_sql)
if self.allocate_procedure_name not in existing_procedures:
frappe.db.sql(self.allocate_procedure_sql)
frappe.db.sql(f"drop table if exists `{self._voucher_balance_name}`")
frappe.db.sql(self._voucher_balance_definition)
frappe.db.sql(f"drop table if exists `{self._row_def_table_name}`")
frappe.db.sql(self._row_def_table_definition)

View File

@@ -8,6 +8,7 @@ from typing import TYPE_CHECKING, Optional
import frappe
import frappe.defaults
from frappe import _, qb, throw
from frappe.desk.reportview import build_match_conditions
from frappe.model.meta import get_field_precision
from frappe.query_builder import AliasedQuery, Criterion, Table
from frappe.query_builder.functions import Round, Sum
@@ -2191,3 +2192,19 @@ def run_ledger_health_checks():
doc.general_and_payment_ledger_mismatch = True
doc.checked_on = run_date
doc.save()
def build_qb_match_conditions(doctype, user=None) -> list:
match_filters = build_match_conditions(doctype, user, False)
criterion = []
if match_filters:
from frappe import qb
_dt = qb.DocType(doctype)
for filter in match_filters:
for d, names in filter.items():
fieldname = d.lower().replace(" ", "_")
criterion.append(_dt[fieldname].isin(names))
return criterion