From 13165f159582e9d4b9d8addba4a9ce73d7ff7823 Mon Sep 17 00:00:00 2001 From: mreficent Date: Mon, 20 May 2019 17:02:38 +0200 Subject: [PATCH 1/2] [FIX] Wrong outstanding amounts for partial reconciliations --- customer_activity_statement/__manifest__.py | 2 +- .../report/customer_activity_statement.py | 61 +++------ .../__manifest__.py | 2 +- .../report/customer_outstanding_statement.py | 119 ++++++------------ 4 files changed, 58 insertions(+), 126 deletions(-) diff --git a/customer_activity_statement/__manifest__.py b/customer_activity_statement/__manifest__.py index 41daefad..29035dd3 100644 --- a/customer_activity_statement/__manifest__.py +++ b/customer_activity_statement/__manifest__.py @@ -5,7 +5,7 @@ { 'name': 'Customer Activity Statement', - 'version': '10.0.1.1.0', + 'version': '10.0.1.1.1', 'category': 'Accounting & Finance', 'summary': 'OCA Financial Reports', 'author': "Eficent, Odoo Community Association (OCA)", diff --git a/customer_activity_statement/report/customer_activity_statement.py b/customer_activity_statement/report/customer_activity_statement.py index 5e3a9259..ee5dafe6 100644 --- a/customer_activity_statement/report/customer_activity_statement.py +++ b/customer_activity_statement/report/customer_activity_statement.py @@ -148,34 +148,6 @@ class CustomerActivityStatement(models.AbstractModel): GROUP BY pr2.id, Q0a.credit_date, Q0b.debit_date """ % (self._get_credit_date(), self._get_debit_date()) - 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.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pd ON pd.debit_move_id = l1.id - LEFT JOIN (SELECT pr.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pc ON pc.credit_move_id = l1.id - GROUP BY l1.id - """ % (self._get_reconcile_date(), date_end, - self._get_reconcile_date(), 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, @@ -194,27 +166,34 @@ class CustomerActivityStatement(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.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id + ON pr.credit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pd ON pd.debit_move_id = l.id - LEFT JOIN (SELECT pr.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id + ON pr.debit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pc ON pc.credit_move_id = l.id WHERE l.partner_id IN (%s) AND at.type = 'receivable' - AND (Q0.reconciled_date is null or - Q0.reconciled_date > '%s') - AND l.date <= '%s' AND not l.blocked + AND ( + (pd.id IS NOT NULL AND + pd.max_date <= '%s') OR + (pc.id IS NOT NULL AND + pc.max_date <= '%s') OR + (pd.id IS NULL AND pc.id IS NULL) + ) 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) + """ % (self._get_reconcile_date(), date_end, + self._get_reconcile_date(), date_end, partners, + date_end, date_end, date_end) def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90, minus_120): @@ -314,15 +293,13 @@ class CustomerActivityStatement(models.AbstractModel): full_dates = self._get_bucket_dates(date_end) # pylint: disable=E8103 self.env.cr.execute(""" - WITH Q0 AS (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s), Q4 AS (%s) + WITH 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 - AS balance + b_90_120, b_over_120, + current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120 AS balance 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( full_dates['date_end'], diff --git a/customer_outstanding_statement/__manifest__.py b/customer_outstanding_statement/__manifest__.py index b5e5fdf5..22987ffa 100644 --- a/customer_outstanding_statement/__manifest__.py +++ b/customer_outstanding_statement/__manifest__.py @@ -5,7 +5,7 @@ { 'name': 'Customer Outstanding Statement', - 'version': '10.0.1.1.0', + 'version': '10.0.1.1.1', 'category': 'Accounting & Finance', 'summary': 'OCA Financial Reports', 'author': "Eficent, Odoo Community Association (OCA)", diff --git a/customer_outstanding_statement/report/customer_outstanding_statement.py b/customer_outstanding_statement/report/customer_outstanding_statement.py index 1caae334..4fb3ab26 100644 --- a/customer_outstanding_statement/report/customer_outstanding_statement.py +++ b/customer_outstanding_statement/report/customer_outstanding_statement.py @@ -19,34 +19,6 @@ 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.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pd ON pd.debit_move_id = l1.id - LEFT JOIN (SELECT pr.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pc ON pc.credit_move_id = l1.id - GROUP BY l1.id - """ % (self._get_reconcile_date(), date_end, - self._get_reconcile_date(), 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, @@ -74,27 +46,34 @@ 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.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id + ON pr.credit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pd ON pd.debit_move_id = l.id - LEFT JOIN (SELECT pr.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id + ON pr.debit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pc ON pc.credit_move_id = l.id WHERE l.partner_id IN (%s) AND at.type = 'receivable' - AND (Q0.reconciled_date is null or - Q0.reconciled_date > '%s') - AND l.date <= '%s' + AND ( + (pd.id IS NOT NULL AND + pd.max_date <= '%s') OR + (pc.id IS NOT NULL AND + pc.max_date <= '%s') OR + (pd.id IS NULL AND pc.id IS NULL) + ) 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) + """ % (self._get_reconcile_date(), date_end, + self._get_reconcile_date(), date_end, partners, + date_end, date_end, date_end) def _display_lines_sql_q2(self): return """ @@ -124,12 +103,11 @@ class CustomerOutstandingStatement(models.AbstractModel): date_end, DEFAULT_SERVER_DATE_FORMAT).date() # pylint: disable=E8103 self.env.cr.execute(""" - WITH Q0 as (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s) + WITH 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 + 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))) @@ -166,34 +144,6 @@ class CustomerOutstandingStatement(models.AbstractModel): GROUP BY pr2.id, Q0a.credit_date, Q0b.debit_date """ % (self._get_credit_date(), self._get_debit_date()) - 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.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pd ON pd.debit_move_id = l1.id - LEFT JOIN (SELECT pr.*, Q0c.max_date - FROM account_partial_reconcile pr - INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id - LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id - WHERE l2.date <= '%s' - ) as pc ON pc.credit_move_id = l1.id - GROUP BY l1.id - """ % (self._get_reconcile_date(), date_end, - self._get_reconcile_date(), 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, @@ -212,27 +162,34 @@ 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.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.credit_move_id = l2.id + ON pr.credit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pd ON pd.debit_move_id = l.id - LEFT JOIN (SELECT pr.* + LEFT JOIN (SELECT pr.*, Q0c.max_date FROM account_partial_reconcile pr INNER JOIN account_move_line l2 - ON pr.debit_move_id = l2.id + ON pr.debit_move_id = l2.id + LEFT JOIN (%s) as Q0c ON Q0c.id = pr.id WHERE l2.date <= '%s' ) as pc ON pc.credit_move_id = l.id WHERE l.partner_id IN (%s) AND at.type = 'receivable' - AND (Q0.reconciled_date is null or - Q0.reconciled_date > '%s') - AND l.date <= '%s' AND not l.blocked + AND ( + (pd.id IS NOT NULL AND + pd.max_date <= '%s') OR + (pc.id IS NOT NULL AND + pc.max_date <= '%s') OR + (pd.id IS NULL AND pc.id IS NULL) + ) 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) + """ % (self._get_reconcile_date(), date_end, + self._get_reconcile_date(), date_end, partners, + date_end, date_end, date_end) def _show_buckets_sql_q2(self, date_end, minus_30, minus_60, minus_90, minus_120): @@ -332,15 +289,13 @@ class CustomerOutstandingStatement(models.AbstractModel): full_dates = self._get_bucket_dates(date_end) # pylint: disable=E8103 self.env.cr.execute(""" - WITH Q0 AS (%s), Q1 AS (%s), Q2 AS (%s), Q3 AS (%s), Q4 AS (%s) + WITH 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 - AS balance + b_90_120, b_over_120, + current+b_1_30+b_30_60+b_60_90+b_90_120+b_over_120 AS balance 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( full_dates['date_end'], From ed53fd31498b7ca0063f7a46c73244eedca7a962 Mon Sep 17 00:00:00 2001 From: Graeme Gellatly Date: Sun, 2 Jun 2019 23:17:35 +1200 Subject: [PATCH 2/2] [FIX] Aging Buckets In certain scenarios involving mutliple payments for multiple invoices, where the reconciliation happens together and the debit move is the smaller item the aging duplicates its value, making the balance greater than it should be. This fix works by preventing moves where different lines are both partial reconciled being grouped together by adding the lines id to the group by clause of _show_buckets_sql_q1 --- .../report/customer_activity_statement.py | 2 +- .../report/customer_outstanding_statement.py | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/customer_activity_statement/report/customer_activity_statement.py b/customer_activity_statement/report/customer_activity_statement.py index ee5dafe6..ca226f73 100644 --- a/customer_activity_statement/report/customer_activity_statement.py +++ b/customer_activity_statement/report/customer_activity_statement.py @@ -190,7 +190,7 @@ class CustomerActivityStatement(models.AbstractModel): ) 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 + l.company_id, l.id """ % (self._get_reconcile_date(), date_end, self._get_reconcile_date(), date_end, partners, date_end, date_end, date_end) diff --git a/customer_outstanding_statement/report/customer_outstanding_statement.py b/customer_outstanding_statement/report/customer_outstanding_statement.py index 4fb3ab26..b0b905df 100644 --- a/customer_outstanding_statement/report/customer_outstanding_statement.py +++ b/customer_outstanding_statement/report/customer_outstanding_statement.py @@ -186,7 +186,7 @@ class CustomerOutstandingStatement(models.AbstractModel): ) 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 + l.company_id, l.id """ % (self._get_reconcile_date(), date_end, self._get_reconcile_date(), date_end, partners, date_end, date_end, date_end)