From e8450d9892ebc12eda42a81236b70741003a92c9 Mon Sep 17 00:00:00 2001 From: mreficent Date: Mon, 26 Feb 2018 17:13:44 +0100 Subject: [PATCH] [FIX] Consider reconciled_date and fix aging report --- customer_outstanding_statement/__init__.py | 1 - .../report/customer_outstanding_statement.py | 110 ++++++++++++++---- .../views/statement.xml | 9 +- 3 files changed, 91 insertions(+), 29 deletions(-) diff --git a/customer_outstanding_statement/__init__.py b/customer_outstanding_statement/__init__.py index 88ee80ef..997d84a6 100644 --- a/customer_outstanding_statement/__init__.py +++ b/customer_outstanding_statement/__init__.py @@ -2,4 +2,3 @@ from . import report from . import wizard -from . import tests diff --git a/customer_outstanding_statement/report/customer_outstanding_statement.py b/customer_outstanding_statement/report/customer_outstanding_statement.py index e37c77f9..b5de5071 100644 --- a/customer_outstanding_statement/report/customer_outstanding_statement.py +++ b/customer_outstanding_statement/report/customer_outstanding_statement.py @@ -18,6 +18,31 @@ class CustomerOutstandingStatement(models.AbstractModel): date = datetime.strptime(str_date, DEFAULT_SERVER_DATE_FORMAT).date() return date.strftime(lang.date_format) + def _display_lines_sql_q0(self, date_end): + return """ + SELECT l1.id, + CASE WHEN l1.reconciled = TRUE and l1.balance > 0.0 + THEN max(pd.max_date) + WHEN l1.reconciled = TRUE and l1.balance < 0.0 + THEN max(pc.max_date) + ELSE null + END as reconciled_date + FROM account_move_line l1 + LEFT JOIN (SELECT pr.* + FROM account_partial_reconcile pr + INNER JOIN account_move_line l2 + ON pr.credit_move_id = l2.id + WHERE l2.date <= '%s' + ) as pd ON pd.debit_move_id = l1.id + LEFT JOIN (SELECT pr.* + FROM account_partial_reconcile pr + INNER JOIN account_move_line l2 + ON pr.debit_move_id = l2.id + WHERE l2.date <= '%s' + ) as pc ON pc.credit_move_id = l1.id + GROUP BY l1.id + """ % (date_end, date_end) + def _display_lines_sql_q1(self, partners, date_end): return """ SELECT m.name as move_id, l.partner_id, l.date, l.name, @@ -45,6 +70,7 @@ class CustomerOutstandingStatement(models.AbstractModel): FROM account_move_line l JOIN account_account_type at ON (at.id = l.user_type_id) JOIN account_move m ON (l.move_id = m.id) + LEFT JOIN Q0 ON Q0.id = l.id LEFT JOIN (SELECT pr.* FROM account_partial_reconcile pr INNER JOIN account_move_line l2 @@ -58,11 +84,13 @@ class CustomerOutstandingStatement(models.AbstractModel): WHERE l2.date <= '%s' ) as pc ON pc.credit_move_id = l.id WHERE l.partner_id IN (%s) AND at.type = 'receivable' - AND not l.reconciled AND l.date <= '%s' + AND (Q0.reconciled_date is null or + Q0.reconciled_date > '%s') + AND l.date <= '%s' GROUP BY l.partner_id, m.name, l.date, l.date_maturity, l.name, l.ref, l.blocked, l.currency_id, l.balance, l.amount_currency, l.company_id - """ % (date_end, date_end, partners, date_end) + """ % (date_end, date_end, partners, date_end, date_end) def _display_lines_sql_q2(self): return """ @@ -91,11 +119,13 @@ class CustomerOutstandingStatement(models.AbstractModel): date_end = datetime.strptime( date_end, DEFAULT_SERVER_DATE_FORMAT).date() # pylint: disable=E8103 - self.env.cr.execute("""WITH Q1 AS (%s), Q2 AS (%s), Q3 AS (%s) + self.env.cr.execute(""" + WITH Q0 as (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s) SELECT partner_id, currency_id, move_id, date, date_maturity, debit, credit, amount, open_amount, name, ref, blocked FROM Q3 ORDER BY date, date_maturity, move_id""" % ( + self._display_lines_sql_q0(date_end), self._display_lines_sql_q1(partners, date_end), self._display_lines_sql_q2(), self._display_lines_sql_q3(company_id))) @@ -103,6 +133,31 @@ class CustomerOutstandingStatement(models.AbstractModel): res[row.pop('partner_id')].append(row) return res + def _show_buckets_sql_q0(self, date_end): + return """ + SELECT l1.id, + CASE WHEN l1.reconciled = TRUE and l1.balance > 0.0 + THEN max(pd.max_date) + WHEN l1.reconciled = TRUE and l1.balance < 0.0 + THEN max(pc.max_date) + ELSE null + END as reconciled_date + FROM account_move_line l1 + LEFT JOIN (SELECT pr.* + FROM account_partial_reconcile pr + INNER JOIN account_move_line l2 + ON pr.credit_move_id = l2.id + WHERE l2.date <= '%s' + ) as pd ON pd.debit_move_id = l1.id + LEFT JOIN (SELECT pr.* + FROM account_partial_reconcile pr + INNER JOIN account_move_line l2 + ON pr.debit_move_id = l2.id + WHERE l2.date <= '%s' + ) as pc ON pc.credit_move_id = l1.id + GROUP BY l1.id + """ % (date_end, date_end) + def _show_buckets_sql_q1(self, partners, date_end): return """ SELECT l.partner_id, l.currency_id, l.company_id, l.move_id, @@ -121,6 +176,7 @@ class CustomerOutstandingStatement(models.AbstractModel): FROM account_move_line l JOIN account_account_type at ON (at.id = l.user_type_id) JOIN account_move m ON (l.move_id = m.id) + LEFT JOIN Q0 ON Q0.id = l.id LEFT JOIN (SELECT pr.* FROM account_partial_reconcile pr INNER JOIN account_move_line l2 @@ -134,15 +190,16 @@ class CustomerOutstandingStatement(models.AbstractModel): WHERE l2.date <= '%s' ) as pc ON pc.credit_move_id = l.id WHERE l.partner_id IN (%s) AND at.type = 'receivable' - AND not l.reconciled AND not l.blocked + AND (Q0.reconciled_date is null or + Q0.reconciled_date > '%s') + AND l.date <= '%s' AND not l.blocked GROUP BY l.partner_id, l.currency_id, l.date, l.date_maturity, l.amount_currency, l.balance, l.move_id, l.company_id - """ % (date_end, date_end, partners) + """ % (date_end, date_end, partners, date_end, date_end) - def _show_buckets_sql_q2(self, today, minus_30, minus_60, minus_90, + def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90, minus_120): - # pylint: disable=E8103 return """ SELECT partner_id, currency_id, date_maturity, open_due, open_due_currency, move_id, company_id, @@ -195,10 +252,10 @@ class CustomerOutstandingStatement(models.AbstractModel): FROM Q1 GROUP BY partner_id, currency_id, date_maturity, open_due, open_due_currency, move_id, company_id - """ % (today, today, minus_30, today, minus_30, today, minus_60, - minus_30, minus_60, minus_30, minus_90, minus_60, minus_90, - minus_60, minus_120, minus_90, minus_120, minus_90, minus_120, - minus_120) + """ % (date_end, date_end, minus_30, date_end, minus_30, date_end, + minus_60, minus_30, minus_60, minus_30, minus_90, minus_60, + minus_90, minus_60, minus_120, minus_90, minus_120, minus_90, + minus_120, minus_120) def _show_buckets_sql_q3(self, company_id): return """ @@ -222,22 +279,24 @@ class CustomerOutstandingStatement(models.AbstractModel): GROUP BY partner_id, currency_id """ - _bucket_dates = { - 'today': fields.date.today(), - 'minus_30': fields.date.today() - timedelta(days=30), - 'minus_60': fields.date.today() - timedelta(days=60), - 'minus_90': fields.date.today() - timedelta(days=90), - 'minus_120': fields.date.today() - timedelta(days=120), - } + def _get_bucket_dates(self, date_end): + return { + 'date_end': date_end, + 'minus_30': date_end - timedelta(days=30), + 'minus_60': date_end - timedelta(days=60), + 'minus_90': date_end - timedelta(days=90), + 'minus_120': date_end - timedelta(days=120), + } def _get_account_show_buckets(self, company_id, partner_ids, date_end): res = dict(map(lambda x: (x, []), partner_ids)) partners = ', '.join([str(i) for i in partner_ids]) date_end = datetime.strptime( date_end, DEFAULT_SERVER_DATE_FORMAT).date() + full_dates = self._get_bucket_dates(date_end) # pylint: disable=E8103 - self.env.cr.execute("""WITH Q1 AS (%s), Q2 AS (%s), - Q3 AS (%s), Q4 AS (%s) + self.env.cr.execute(""" + WITH Q0 AS (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s), Q4 AS (%s) SELECT partner_id, currency_id, current, b_1_30, b_30_60, b_60_90, b_90_120, b_over_120, current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120 @@ -245,13 +304,14 @@ class CustomerOutstandingStatement(models.AbstractModel): FROM Q4 GROUP BY partner_id, currency_id, current, b_1_30, b_30_60, b_60_90, b_90_120, b_over_120""" % ( + self._show_buckets_sql_q0(date_end), self._show_buckets_sql_q1(partners, date_end), self._show_buckets_sql_q2( - self._bucket_dates['today'], - self._bucket_dates['minus_30'], - self._bucket_dates['minus_60'], - self._bucket_dates['minus_90'], - self._bucket_dates['minus_120']), + full_dates['date_end'], + full_dates['minus_30'], + full_dates['minus_60'], + full_dates['minus_90'], + full_dates['minus_120']), self._show_buckets_sql_q3(company_id), self._show_buckets_sql_q4())) for row in self.env.cr.dictfetchall(): diff --git a/customer_outstanding_statement/views/statement.xml b/customer_outstanding_statement/views/statement.xml index b83596d9..76f081e9 100644 --- a/customer_outstanding_statement/views/statement.xml +++ b/customer_outstanding_statement/views/statement.xml @@ -11,11 +11,11 @@ -

+

Outstanding Statement

- Date:
+ Date:
Partner ref:

@@ -24,7 +24,7 @@

- Outstanding Statement in : + Outstanding Statement at in :

@@ -116,6 +116,9 @@
+

+ Aging Report at in : +