refactor: using sql procedures for AR report

- dynamic filters are passed

(cherry picked from commit e5920c57aa)

# Conflicts:
#	erpnext/accounts/report/accounts_receivable/accounts_receivable.py
This commit is contained in:
ruthra kumar
2025-05-02 13:46:46 +05:30
committed by Mergify
parent 9dad08274a
commit da1dcb8b21

View File

@@ -115,6 +115,14 @@ class ReceivablePayableReport:
elif self.ple_fetch_method == "UnBuffered Cursor":
self.fetch_ple_in_unbuffered_cursor()
<<<<<<< HEAD
=======
self.init_and_run_sql_procedures()
# Build delivery note map against all sales invoices
self.build_delivery_note_map()
>>>>>>> e5920c57aa (refactor: using sql procedures for AR report)
self.build_data()
def fetch_ple_in_buffered_cursor(self):
@@ -299,6 +307,179 @@ class ReceivablePayableReport:
row.paid -= amount
row.paid_in_account_currency -= amount_in_account_currency
def init_and_run_sql_procedures(self):
# create in-memory temporary table for performance
frappe.db.sql("drop table if exists voucher_balance;")
# Memory storage engine doesn't support remarks - BLOB, TEXT types.
# Alternative?
frappe.db.sql(
"""
create temporary table voucher_balance(
name varchar(224),
voucher_type varchar(140),
voucher_no varchar(140),
party varchar(140),
party_account varchar(140),
posting_date date,
account_currency varchar(140),
invoiced decimal(21,9),
paid decimal(21,9),
credit_note decimal(21,9),
outstanding decimal(21,9),
invoiced_in_account_currency decimal(21,9),
paid_in_account_currency decimal(21,9),
credit_note_in_account_currency decimal(21,9),
outstanding_in_account_currency decimal(21,9)) engine=memory;
"""
)
# Only used for passing definitions to 'row type of'
frappe.db.sql("drop table if exists ple_row;")
frappe.db.sql(
"""
create temporary table ple_row(
name varchar(224),
account varchar(140),
voucher_type varchar(140),
voucher_no varchar(140),
against_voucher_type varchar(140),
against_voucher_no varchar(140),
party_type varchar(140),
cost_center varchar(140),
party varchar(140),
posting_date date,
due_date date,
account_currency varchar(140),
amount decimal(21,9),
amount_in_account_currency decimal(21,9)) engine=memory;
"""
)
# Generate hash from key
frappe.db.sql("drop function if exists genkey;")
frappe.db.sql(
"""
create function genkey(rec row type of ple_row, allocate bool) returns char(224)
begin
if allocate then
return sha2(concat_ws(',', rec.account, rec.against_voucher_type, rec.against_voucher_no, rec.party), 224);
else
return sha2(concat_ws(',', rec.account, rec.voucher_type, rec.voucher_no, rec.party), 224);
end if;
end
"""
)
# Init
frappe.db.sql("drop procedure if exists init;")
init_procedure = """
create procedure init(in ple row type of `ple_row`)
begin
if not exists (select name from `voucher_balance` where name = genkey(ple, false))
then
insert into `voucher_balance` values (genkey(ple, false), ple.voucher_type, ple.voucher_no, ple.party, ple.account, ple.posting_date, ple.account_currency, 0, 0, 0, 0, 0, 0, 0, 0);
end if;
end;
"""
frappe.db.sql(init_procedure)
# Allocate
frappe.db.sql("drop procedure if exists allocate;")
allocate_procedure = """
create procedure allocate(in ple row type of `ple_row`)
begin
declare invoiced decimal(21,9) default 0;
declare invoiced_in_account_currency decimal(21,9) default 0;
declare paid decimal(21,9) default 0;
declare paid_in_account_currency decimal(21,9) default 0;
declare credit_note decimal(21,9) default 0;
declare credit_note_in_account_currency decimal(21,9) 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` values (genkey(ple, true), ple.against_voucher_type, ple.against_voucher_no, ple.party, ple.account, ple.posting_date, ple.account_currency, invoiced, paid, 0, 0, invoiced_in_account_currency, paid_in_account_currency, 0, 0);
end;
"""
frappe.db.sql(allocate_procedure)
frappe.db.sql("drop procedure if exists build;")
build_balance = f"""
begin not atomic
declare done boolean default false;
declare rec1 row type of ple_row;
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 init(rec1);
fetch ple into rec1;
end while;
close ple;
set done = false;
open ple;
fetch ple into rec1;
while not done do
call allocate(rec1);
fetch ple into rec1;
end while;
close ple;
end;
"""
frappe.db.sql(build_balance)
res = frappe.db.sql(
"""select
name,
voucher_type,
voucher_no,
party,
party_account,
posting_date,
account_currency,
sum(invoiced),
sum(paid),
sum(credit_note),
sum(invoiced) - sum(paid) - sum(credit_note),
sum(invoiced_in_account_currency),
sum(paid_in_account_currency),
sum(credit_note_in_account_currency),
sum(invoiced_in_account_currency) - sum(paid_in_account_currency) - sum(credit_note_in_account_currency)
from `voucher_balance` group by name;"""
)
self.printv(res)
def printv(self, res):
for x in res:
# if x[3] == "ACC-SINV-2025-00035":
print(x)
def update_sub_total_row(self, row, party):
total_row = self.total_row_map.get(party)