Replaced the SQL query in the cash account summary with the Django model query in the accounting application.
This commit is contained in:
parent
b20b82698b
commit
b8eb78cc9f
@ -231,68 +231,48 @@ def cash_summary(request, subject_code):
|
|||||||
if current_subject is None:
|
if current_subject is None:
|
||||||
raise Http404()
|
raise Http404()
|
||||||
# The accounting records
|
# The accounting records
|
||||||
if connection.vendor == "postgresql":
|
|
||||||
month_definition = "CAST(DATE_TRUNC('month', t.date) AS date)"
|
|
||||||
elif connection.vendor == "sqlite":
|
|
||||||
month_definition = "DATE(t.date, 'start of month')"
|
|
||||||
else:
|
|
||||||
month_definition = None
|
|
||||||
q = Transaction.objects.filter(
|
|
||||||
Q(record__subject__code__startswith="11") |
|
|
||||||
Q(record__subject__code__startswith="12") |
|
|
||||||
Q(record__subject__code__startswith="21") |
|
|
||||||
Q(record__subject__code__startswith="22")).values("sn")
|
|
||||||
if current_subject.code == "0":
|
if current_subject.code == "0":
|
||||||
records = list(RecordSummary.objects.raw(
|
records = [RecordSummary(**x) for x in Record.objects.filter(
|
||||||
f"""SELECT
|
Q(transaction__in=Transaction.objects.filter(
|
||||||
{month_definition} AS month,
|
Q(record__subject__code__startswith="11") |
|
||||||
SUM(CASE WHEN r.is_credit THEN r.amount ELSE 0 END) AS credit,
|
Q(record__subject__code__startswith="12") |
|
||||||
SUM(CASE WHEN r.is_credit THEN 0 ELSE r.amount END) AS debit,
|
Q(record__subject__code__startswith="21") |
|
||||||
SUM(CASE WHEN r.is_credit THEN 1 ELSE -1 END * r.amount) AS balance
|
Q(record__subject__code__startswith="22"))),
|
||||||
FROM accounting_records AS r
|
~Q(subject__code__startswith="11"),
|
||||||
INNER JOIN (SELECT
|
~Q(subject__code__startswith="12"),
|
||||||
t1.sn AS sn,
|
~Q(subject__code__startswith="21"),
|
||||||
t1.date AS date,
|
~Q(subject__code__startswith="22")) \
|
||||||
t1.ord AS ord
|
.annotate(month=TruncMonth("transaction__date")) \
|
||||||
FROM accounting_records AS r1
|
.values("month") \
|
||||||
LEFT JOIN accounting_transactions AS t1 ON r1.transaction_sn=t1.sn
|
.order_by("month") \
|
||||||
LEFT JOIN accounting_subjects AS s1 ON r1.subject_sn = s1.sn
|
.annotate(
|
||||||
WHERE s1.code LIKE '11%%'
|
debit=Coalesce(
|
||||||
OR s1.code LIKE '12%%'
|
Sum(Case(When(is_credit=False, then=F("amount")))),
|
||||||
OR s1.code LIKE '21%%'
|
0),
|
||||||
OR s1.code LIKE '22%%'
|
credit=Coalesce(
|
||||||
GROUP BY t1.sn) AS t
|
Sum(Case(When(is_credit=True, then=F("amount")))),
|
||||||
ON r.transaction_sn=t.sn
|
0),
|
||||||
LEFT JOIN accounting_subjects AS s ON r.subject_sn = s.sn
|
balance=Sum(Case(
|
||||||
WHERE s.code NOT LIKE '11%%'
|
When(is_credit=False, then=-F("amount")),
|
||||||
AND s.code NOT LIKE '12%%'
|
default=F("amount"))))]
|
||||||
AND s.code NOT LIKE '21%%'
|
|
||||||
AND s.code NOT LIKE '22%%'
|
|
||||||
GROUP BY month
|
|
||||||
ORDER BY month"""))
|
|
||||||
else:
|
else:
|
||||||
records = list(RecordSummary.objects.raw(
|
records = [RecordSummary(**x) for x in Record.objects.filter(
|
||||||
f"""SELECT
|
Q(transaction__in=Transaction.objects.filter(
|
||||||
{month_definition} AS month,
|
record__subject__code__startswith=current_subject.code)),
|
||||||
SUM(CASE WHEN r.is_credit THEN r.amount ELSE 0 END) AS credit,
|
~Q(subject__code__startswith=current_subject.code)) \
|
||||||
SUM(CASE WHEN r.is_credit THEN 0 ELSE r.amount END) AS debit,
|
.annotate(month=TruncMonth("transaction__date")) \
|
||||||
SUM(CASE WHEN r.is_credit THEN 1 ELSE -1 END * r.amount) AS balance
|
.values("month") \
|
||||||
FROM accounting_records AS r
|
.order_by("month") \
|
||||||
INNER JOIN (SELECT
|
.annotate(
|
||||||
t1.sn AS sn,
|
debit=Coalesce(
|
||||||
t1.date AS date,
|
Sum(Case(When(is_credit=False, then=F("amount")))),
|
||||||
t1.ord AS ord
|
0),
|
||||||
FROM accounting_records AS r1
|
credit=Coalesce(
|
||||||
LEFT JOIN accounting_transactions AS t1 ON r1.transaction_sn=t1.sn
|
Sum(Case(When(is_credit=True, then=F("amount")))),
|
||||||
LEFT JOIN accounting_subjects AS s1 ON r1.subject_sn = s1.sn
|
0),
|
||||||
WHERE s1.code LIKE %s
|
balance=Sum(Case(
|
||||||
GROUP BY t1.sn) AS t
|
When(is_credit=False, then=-F("amount")),
|
||||||
ON r.transaction_sn=t.sn
|
default=F("amount"))))]
|
||||||
LEFT JOIN accounting_subjects AS s ON r.subject_sn = s.sn
|
|
||||||
WHERE s.code NOT LIKE %s
|
|
||||||
GROUP BY month
|
|
||||||
ORDER BY month""",
|
|
||||||
[current_subject.code + "%", current_subject.code + "%"]))
|
|
||||||
cumulative_balance = 0
|
cumulative_balance = 0
|
||||||
for record in records:
|
for record in records:
|
||||||
cumulative_balance = cumulative_balance + record.balance
|
cumulative_balance = cumulative_balance + record.balance
|
||||||
|
Loading…
Reference in New Issue
Block a user