Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

fix: refactor query inget_total_allocated_amount in bank_transaction (backport #44787) #44897

Open
wants to merge 2 commits into
base: version-15-hotfix
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -480,8 +480,12 @@ def get_linked_payments(
def subtract_allocations(gl_account, vouchers):
"Look up & subtract any existing Bank Transaction allocations"
copied = []

voucher_docs = [(voucher.get("doctype"), voucher.get("name")) for voucher in vouchers]
voucher_allocated_amounts = get_total_allocated_amount(voucher_docs)

for voucher in vouchers:
rows = get_total_allocated_amount(voucher.get("doctype"), voucher.get("name"))
rows = voucher_allocated_amounts.get((voucher.get("doctype"), voucher.get("name"))) or []
filtered_row = list(filter(lambda row: row.get("gl_account") == gl_account, rows))

if amount := None if not filtered_row else filtered_row[0]["total"]:
Expand Down
37 changes: 25 additions & 12 deletions erpnext/accounts/doctype/bank_transaction/bank_transaction.py
Original file line number Diff line number Diff line change
Expand Up @@ -154,10 +154,16 @@ def allocate_payment_entries(self):
"""
remaining_amount = self.unallocated_amount
to_remove = []
payment_entry_docs = [(pe.payment_document, pe.payment_entry) for pe in self.payment_entries]
pe_bt_allocations = get_total_allocated_amount(payment_entry_docs)

for payment_entry in self.payment_entries:
if payment_entry.allocated_amount == 0.0:
unallocated_amount, should_clear, latest_transaction = get_clearance_details(
self, payment_entry
self,
payment_entry,
pe_bt_allocations.get((payment_entry.payment_document, payment_entry.payment_entry))
or [],
)

if 0.0 == unallocated_amount:
Expand Down Expand Up @@ -232,7 +238,7 @@ def get_doctypes_for_bank_reconciliation():
return frappe.get_hooks("bank_reconciliation_doctypes")


def get_clearance_details(transaction, payment_entry):
def get_clearance_details(transaction, payment_entry, bt_allocations):
"""
There should only be one bank gle for a voucher.
Could be none for a Bank Transaction.
Expand All @@ -241,7 +247,6 @@ def get_clearance_details(transaction, payment_entry):
"""
gl_bank_account = frappe.db.get_value("Bank Account", transaction.bank_account, "account")
gles = get_related_bank_gl_entries(payment_entry.payment_document, payment_entry.payment_entry)
bt_allocations = get_total_allocated_amount(payment_entry.payment_document, payment_entry.payment_entry)

unallocated_amount = min(
transaction.unallocated_amount,
Expand Down Expand Up @@ -294,44 +299,52 @@ def get_related_bank_gl_entries(doctype, docname):
)


def get_total_allocated_amount(doctype, docname):
def get_total_allocated_amount(docs):
"""
Gets the sum of allocations for a voucher on each bank GL account
along with the latest bank transaction name & date
NOTE: query may also include just saved vouchers/payments but with zero allocated_amount
"""
if not docs:
return {}

# nosemgrep: frappe-semgrep-rules.rules.frappe-using-db-sql
result = frappe.db.sql(
"""
SELECT total, latest_name, latest_date, gl_account FROM (
SELECT total, latest_name, latest_date, gl_account, payment_document, payment_entry FROM (
SELECT
ROW_NUMBER() OVER w AS rownum,
SUM(btp.allocated_amount) OVER(PARTITION BY ba.account) AS total,
SUM(btp.allocated_amount) OVER(PARTITION BY ba.account, btp.payment_document, btp.payment_entry) AS total,
FIRST_VALUE(bt.name) OVER w AS latest_name,
FIRST_VALUE(bt.date) OVER w AS latest_date,
ba.account AS gl_account
ba.account AS gl_account,
btp.payment_document,
btp.payment_entry
FROM
`tabBank Transaction Payments` btp
LEFT JOIN `tabBank Transaction` bt ON bt.name=btp.parent
LEFT JOIN `tabBank Account` ba ON ba.name=bt.bank_account
WHERE
btp.payment_document = %(doctype)s
AND btp.payment_entry = %(docname)s
(btp.payment_document, btp.payment_entry) IN %(docs)s
AND bt.docstatus = 1
WINDOW w AS (PARTITION BY ba.account ORDER BY bt.date desc)
WINDOW w AS (PARTITION BY ba.account, btp.payment_document, btp.payment_entry ORDER BY bt.date DESC)
) temp
WHERE
rownum = 1
""",
dict(doctype=doctype, docname=docname),
dict(docs=docs),
as_dict=True,
)

payment_allocation_details = {}
for row in result:
# Why is this *sometimes* a byte string?
if isinstance(row["latest_name"], bytes):
row["latest_name"] = row["latest_name"].decode()
row["latest_date"] = frappe.utils.getdate(row["latest_date"])
return result
payment_allocation_details.setdefault((row["payment_document"], row["payment_entry"]), []).append(row)

return payment_allocation_details


def get_paid_amount(payment_entry, currency, gl_bank_account):
Expand Down
Loading