From 9ad59f8a2b40b1ad2d9b70a05b192c260dccf80a Mon Sep 17 00:00:00 2001 From: jcoux Date: Mon, 5 Sep 2016 11:59:34 +0200 Subject: [PATCH] Performance improvement for OCA accounting reports --- .../report/abstract_report_xlsx.py | 17 + .../report/general_ledger.py | 355 ++++++++++++++---- .../report/open_items.py | 81 ++-- .../report/trial_balance.py | 4 +- 4 files changed, 358 insertions(+), 99 deletions(-) diff --git a/account_financial_report_qweb/report/abstract_report_xlsx.py b/account_financial_report_qweb/report/abstract_report_xlsx.py index 5debe764..041d0f05 100644 --- a/account_financial_report_qweb/report/abstract_report_xlsx.py +++ b/account_financial_report_qweb/report/abstract_report_xlsx.py @@ -3,6 +3,8 @@ # Copyright 2016 Camptocamp SA # License AGPL-3.0 or later (http://www.gnu.org/licenses/agpl.html). +from cStringIO import StringIO +import xlsxwriter from openerp.addons.report_xlsx.report.report_xlsx import ReportXlsx @@ -33,6 +35,21 @@ class AbstractReportXslx(ReportXlsx): self.format_amount = None self.format_percent_bold_italic = None + def create_xlsx_report(self, ids, data, report): + """ Overrides method to add constant_memory option used for large files + """ + self.parser_instance = self.parser( + self.env.cr, self.env.uid, self.name2, self.env.context) + objs = self.getObjects( + self.env.cr, self.env.uid, ids, self.env.context) + self.parser_instance.set_context(objs, data, ids, 'xlsx') + file_data = StringIO() + workbook = xlsxwriter.Workbook(file_data, {'constant_memory': True}) + self.generate_xlsx_report(workbook, data, objs) + workbook.close() + file_data.seek(0) + return (file_data.read(), 'xlsx') + def generate_xlsx_report(self, workbook, data, objects): report = objects diff --git a/account_financial_report_qweb/report/general_ledger.py b/account_financial_report_qweb/report/general_ledger.py index b93b9f16..c2399a53 100644 --- a/account_financial_report_qweb/report/general_ledger.py +++ b/account_financial_report_qweb/report/general_ledger.py @@ -209,11 +209,18 @@ class GeneralLedgerReportCompute(models.TransientModel): report_name=report_name) @api.multi - def compute_data_for_report(self): + def compute_data_for_report(self, + with_line_details=True, + with_partners=True + ): self.ensure_one() # Compute report data self._inject_account_values() - self._inject_partner_values() + + if with_partners: + self._inject_partner_values() + if not self.filter_partner_ids: + self._inject_partner_values(only_empty_partner=True) # Add unaffected earnings account if (not self.filter_account_ids or @@ -221,14 +228,27 @@ class GeneralLedgerReportCompute(models.TransientModel): self.filter_account_ids.ids): self._inject_unaffected_earnings_account_values() - self._inject_line_not_centralized_values() - self._inject_line_not_centralized_values(is_account_line=False, - is_partner_line=True) - self._inject_line_not_centralized_values(is_account_line=False, - is_partner_line=True, - only_empty_partner_line=True) - if self.centralize: - self._inject_line_centralized_values() + # Call this function even if we don't want line details because, + # we need to compute + # at least the values for unaffected earnings account + # In this case, only unaffected earnings account values are computed + only_unaffected_earnings_account = not with_line_details + self._inject_line_not_centralized_values( + only_unaffected_earnings_account=only_unaffected_earnings_account + ) + + if with_line_details: + self._inject_line_not_centralized_values( + is_account_line=False, + is_partner_line=True) + + self._inject_line_not_centralized_values( + is_account_line=False, + is_partner_line=True, + only_empty_partner_line=True) + + if self.centralize: + self._inject_line_centralized_values() # Complete unaffected earnings account if (not self.filter_account_ids or @@ -236,50 +256,84 @@ class GeneralLedgerReportCompute(models.TransientModel): self.filter_account_ids.ids): self._complete_unaffected_earnings_account_values() - # Compute display flag - self._compute_has_second_currency() + if with_line_details: + # Compute display flag + self._compute_has_second_currency() + # Refresh cache because all data are computed with SQL requests self.refresh() - def _inject_account_values(self): - """Inject report values for report_general_ledger_qweb_account.""" - subquery_sum_amounts = """ - SELECT - a.id AS account_id, - SUM(ml.debit) AS debit, - SUM(ml.credit) AS credit, - SUM(ml.balance) AS balance - FROM - accounts a - INNER JOIN - account_account_type at ON a.user_type_id = at.id - INNER JOIN - account_move_line ml - ON a.id = ml.account_id - AND ml.date <= %s - AND - ( - at.include_initial_balance != TRUE AND ml.date >= %s - OR at.include_initial_balance = TRUE - ) + def _get_account_sub_subquery_sum_amounts(self, include_initial_balance): + """ Return subquery used to compute sum amounts on accounts """ + sub_subquery_sum_amounts = """ + SELECT + a.id AS account_id, + SUM(ml.debit) AS debit, + SUM(ml.credit) AS credit, + SUM(ml.balance) AS balance + FROM + accounts a + INNER JOIN + account_account_type at ON a.user_type_id = at.id + INNER JOIN + account_move_line ml + ON a.id = ml.account_id + AND ml.date <= %s """ + + if not include_initial_balance: + sub_subquery_sum_amounts += """ + AND at.include_initial_balance != TRUE AND ml.date >= %s + """ + else: + sub_subquery_sum_amounts += """ + AND at.include_initial_balance = TRUE + """ + if self.only_posted_moves: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_move m ON ml.move_id = m.id AND m.state = 'posted' """ if self.filter_cost_center_ids: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_analytic_account aa ON ml.analytic_account_id = aa.id AND aa.id IN %s """ - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ GROUP BY a.id """ + return sub_subquery_sum_amounts + + def _inject_account_values(self): + """Inject report values for report_general_ledger_qweb_account.""" + subquery_sum_amounts = """ + SELECT + sub.account_id AS account_id, + SUM(COALESCE(sub.debit, 0.0)) AS debit, + SUM(COALESCE(sub.credit, 0.0)) AS credit, + SUM(COALESCE(sub.balance, 0.0)) AS balance + FROM + ( + """ + subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts( + include_initial_balance=False + ) + subquery_sum_amounts += """ + UNION + """ + subquery_sum_amounts += self._get_account_sub_subquery_sum_amounts( + include_initial_balance=True + ) + subquery_sum_amounts += """ + ) sub + GROUP BY + sub.account_id + """ query_inject_account = """ WITH accounts AS @@ -409,6 +463,13 @@ AND self.date_from, self.fy_start_date, ) + if self.filter_cost_center_ids: + query_inject_account_params += ( + tuple(self.filter_cost_center_ids.ids), + ) + query_inject_account_params += ( + self.date_from, + ) if self.filter_cost_center_ids: query_inject_account_params += ( tuple(self.filter_cost_center_ids.ids), @@ -417,6 +478,13 @@ AND self.date_to, self.fy_start_date, ) + if self.filter_cost_center_ids: + query_inject_account_params += ( + tuple(self.filter_cost_center_ids.ids), + ) + query_inject_account_params += ( + self.date_to, + ) if self.filter_cost_center_ids: query_inject_account_params += ( tuple(self.filter_cost_center_ids.ids), @@ -427,12 +495,11 @@ AND ) self.env.cr.execute(query_inject_account, query_inject_account_params) - def _inject_partner_values(self): - """ Inject report values for report_general_ledger_qweb_partner. - - Only for "partner" accounts (payable and receivable). - """ - subquery_sum_amounts = """ + def _get_partner_sub_subquery_sum_amounts( + self, only_empty_partner, include_initial_balance + ): + """ Return subquery used to compute sum amounts on partners """ + sub_subquery_sum_amounts = """ SELECT ap.account_id AS account_id, ap.partner_id AS partner_id, @@ -444,33 +511,75 @@ AND INNER JOIN account_move_line ml ON ap.account_id = ml.account_id - AND ( - ap.partner_id = ml.partner_id - OR ap.partner_id IS NULL AND ml.partner_id IS NULL - ) AND ml.date <= %s - AND ( - ap.include_initial_balance != TRUE AND ml.date >= %s - OR ap.include_initial_balance = TRUE - ) """ + if not only_empty_partner: + sub_subquery_sum_amounts += """ + AND ap.partner_id = ml.partner_id + """ + else: + sub_subquery_sum_amounts += """ + AND ap.partner_id IS NULL AND ml.partner_id IS NULL + """ + if not include_initial_balance: + sub_subquery_sum_amounts += """ + AND ap.include_initial_balance != TRUE AND ml.date >= %s + """ + else: + sub_subquery_sum_amounts += """ + AND ap.include_initial_balance = TRUE + """ if self.only_posted_moves: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_move m ON ml.move_id = m.id AND m.state = 'posted' """ if self.filter_cost_center_ids: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_analytic_account aa ON ml.analytic_account_id = aa.id AND aa.id IN %s """ - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ GROUP BY ap.account_id, ap.partner_id """ + return sub_subquery_sum_amounts + + def _inject_partner_values(self, only_empty_partner=False): + """ Inject report values for report_general_ledger_qweb_partner. + + Only for "partner" accounts (payable and receivable). + """ + subquery_sum_amounts = """ + + SELECT + sub.account_id AS account_id, + sub.partner_id AS partner_id, + SUM(COALESCE(sub.debit, 0.0)) AS debit, + SUM(COALESCE(sub.credit, 0.0)) AS credit, + SUM(COALESCE(sub.balance, 0.0)) AS balance + FROM + ( + """ + subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts( + only_empty_partner, + include_initial_balance=False + ) + subquery_sum_amounts += """ + UNION + """ + subquery_sum_amounts += self._get_partner_sub_subquery_sum_amounts( + only_empty_partner, + include_initial_balance=True + ) + subquery_sum_amounts += """ + ) sub + GROUP BY + sub.account_id, sub.partner_id + """ query_inject_partner = """ WITH accounts_partners AS @@ -514,12 +623,23 @@ WITH ra.report_id = %s AND ra.is_partner_account = TRUE + """ + if not only_empty_partner: + query_inject_partner += """ + AND + p.id IS NOT NULL + """ + else: + query_inject_partner += """ + AND + p.id IS NULL + """ + query_inject_partner += """ """ if self.centralize: query_inject_partner += """ - AND - (a.centralized IS NULL OR a.centralized != TRUE) - """ + AND (a.centralized IS NULL OR a.centralized != TRUE) + """ if self.filter_partner_ids: query_inject_partner += """ AND @@ -567,16 +687,32 @@ LEFT JOIN initial_sum_amounts i ON ( + """ + if not only_empty_partner: + query_inject_partner += """ ap.partner_id = i.partner_id - OR ap.partner_id IS NULL AND i.partner_id IS NULL + """ + else: + query_inject_partner += """ + ap.partner_id IS NULL AND i.partner_id IS NULL + """ + query_inject_partner += """ ) AND ap.account_id = i.account_id LEFT JOIN final_sum_amounts f ON ( + """ + if not only_empty_partner: + query_inject_partner += """ ap.partner_id = f.partner_id - OR ap.partner_id IS NULL AND f.partner_id IS NULL + """ + else: + query_inject_partner += """ + ap.partner_id IS NULL AND f.partner_id IS NULL + """ + query_inject_partner += """ ) AND ap.account_id = f.account_id WHERE @@ -610,6 +746,13 @@ AND self.date_from, self.fy_start_date, ) + if self.filter_cost_center_ids: + query_inject_partner_params += ( + tuple(self.filter_cost_center_ids.ids), + ) + query_inject_partner_params += ( + self.date_from, + ) if self.filter_cost_center_ids: query_inject_partner_params += ( tuple(self.filter_cost_center_ids.ids), @@ -618,6 +761,13 @@ AND self.date_to, self.fy_start_date, ) + if self.filter_cost_center_ids: + query_inject_partner_params += ( + tuple(self.filter_cost_center_ids.ids), + ) + query_inject_partner_params += ( + self.date_to, + ) if self.filter_cost_center_ids: query_inject_partner_params += ( tuple(self.filter_cost_center_ids.ids), @@ -627,10 +777,12 @@ AND ) self.env.cr.execute(query_inject_partner, query_inject_partner_params) - def _inject_line_not_centralized_values(self, - is_account_line=True, - is_partner_line=False, - only_empty_partner_line=False): + def _inject_line_not_centralized_values( + self, + is_account_line=True, + is_partner_line=False, + only_empty_partner_line=False, + only_unaffected_earnings_account=False): """ Inject report values for report_general_ledger_qweb_move_line. If centralized option have been chosen, @@ -797,6 +949,11 @@ WHERE ra.report_id = %s AND """ + if only_unaffected_earnings_account: + query_inject_move_line += """ + a.id = %s +AND + """ if is_account_line: query_inject_move_line += """ (ra.is_partner_account IS NULL OR ra.is_partner_account != TRUE) @@ -851,6 +1008,12 @@ ORDER BY ) query_inject_move_line_params += ( self.id, + ) + if only_unaffected_earnings_account: + query_inject_move_line_params += ( + self.unaffected_earnings_account.id, + ) + query_inject_move_line_params += ( self.date_from, self.date_to, ) @@ -1012,10 +1175,12 @@ WHERE id = %s params = (self.id,) * 3 self.env.cr.execute(query_update_has_second_currency, params) - def _inject_unaffected_earnings_account_values(self): - """Inject the report values of the unaffected earnings account - for report_general_ledger_qweb_account.""" - subquery_sum_amounts = """ + def _get_unaffected_earnings_account_sub_subquery_sum_amounts( + self, include_initial_balance + ): + """ Return subquery used to compute sum amounts on + unaffected earnings accounts """ + sub_subquery_sum_amounts = """ SELECT SUM(ml.balance) AS balance FROM @@ -1026,30 +1191,59 @@ WHERE id = %s account_move_line ml ON a.id = ml.account_id AND ml.date <= %s - AND - NOT( - at.include_initial_balance != TRUE AND ml.date >= %s - OR at.include_initial_balance = TRUE - ) """ + + if not include_initial_balance: + sub_subquery_sum_amounts += """ + AND NOT(at.include_initial_balance != TRUE AND ml.date >= %s) + """ + else: + sub_subquery_sum_amounts += """ + AND at.include_initial_balance = FALSE + """ if self.only_posted_moves: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_move m ON ml.move_id = m.id AND m.state = 'posted' """ if self.filter_cost_center_ids: - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ INNER JOIN account_analytic_account aa ON ml.analytic_account_id = aa.id AND aa.id IN %s """ - subquery_sum_amounts += """ + sub_subquery_sum_amounts += """ WHERE a.company_id =%s AND a.id != %s """ + return sub_subquery_sum_amounts + + def _inject_unaffected_earnings_account_values(self): + """Inject the report values of the unaffected earnings account + for report_general_ledger_qweb_account.""" + subquery_sum_amounts = """ + SELECT + SUM(COALESCE(sub.balance, 0.0)) AS balance + FROM + ( + """ + subquery_sum_amounts += \ + self._get_unaffected_earnings_account_sub_subquery_sum_amounts( + include_initial_balance=False + ) + subquery_sum_amounts += """ + UNION + """ + subquery_sum_amounts += \ + self._get_unaffected_earnings_account_sub_subquery_sum_amounts( + include_initial_balance=True + ) + subquery_sum_amounts += """ + ) sub + """ query_inject_account = """ WITH initial_sum_amounts AS ( """ + subquery_sum_amounts + """ ) @@ -1092,6 +1286,19 @@ WHERE id = %s query_inject_account_params += ( self.company_id.id, self.unaffected_earnings_account.id, + ) + query_inject_account_params += ( + self.date_from, + ) + if self.filter_cost_center_ids: + query_inject_account_params += ( + tuple(self.filter_cost_center_ids.ids), + ) + query_inject_account_params += ( + self.company_id.id, + self.unaffected_earnings_account.id, + ) + query_inject_account_params += ( self.id, self.env.uid, self.company_id.id, diff --git a/account_financial_report_qweb/report/open_items.py b/account_financial_report_qweb/report/open_items.py index ba82ddbf..50a8920f 100644 --- a/account_financial_report_qweb/report/open_items.py +++ b/account_financial_report_qweb/report/open_items.py @@ -339,16 +339,11 @@ FROM ) self.env.cr.execute(query_inject_partner, query_inject_partner_params) - def _inject_line_values(self, only_empty_partner_line=False): - """ Inject report values for report_open_items_qweb_move_line. - - The "only_empty_partner_line" value is used - to compute data without partner. - """ - query_inject_move_line = """ -WITH - move_lines_amount AS - ( + def _get_line_sub_query_move_lines(self, + only_empty_partner_line=False, + positive_balance=True): + """ Return subquery used to compute sum amounts on lines """ + sub_query = """ SELECT ml.id, ml.balance, @@ -377,32 +372,42 @@ WITH ON ra.account_id = ml.account_id """ if not only_empty_partner_line: - query_inject_move_line += """ + sub_query += """ AND rp.partner_id = ml.partner_id """ elif only_empty_partner_line: - query_inject_move_line += """ + sub_query += """ AND ml.partner_id IS NULL """ - query_inject_move_line += """ + if not positive_balance: + sub_query += """ LEFT JOIN account_partial_reconcile pr ON ml.balance < 0 AND pr.credit_move_id = ml.id - OR ml.balance > 0 AND pr.debit_move_id = ml.id LEFT JOIN account_move_line ml_future - ON ( - ml.balance < 0 AND pr.debit_move_id = ml_future.id - OR ml.balance > 0 AND pr.credit_move_id = ml_future.id - ) - AND ml_future.date >= %s + ON ml.balance < 0 AND pr.debit_move_id = ml_future.id + AND ml_future.date >= %s + LEFT JOIN + account_move_line ml_past + ON ml.balance < 0 AND pr.debit_move_id = ml_past.id + AND ml_past.date < %s + """ + else: + sub_query += """ + LEFT JOIN + account_partial_reconcile pr + ON ml.balance > 0 AND pr.debit_move_id = ml.id + LEFT JOIN + account_move_line ml_future + ON ml.balance > 0 AND pr.credit_move_id = ml_future.id + AND ml_future.date >= %s LEFT JOIN account_move_line ml_past - ON ( - ml.balance < 0 AND pr.debit_move_id = ml_past.id - OR ml.balance > 0 AND pr.credit_move_id = ml_past.id - ) - AND ml_past.date < %s + ON ml.balance > 0 AND pr.credit_move_id = ml_past.id + AND ml_past.date < %s + """ + sub_query += """ WHERE ra.report_id = %s GROUP BY @@ -414,7 +419,32 @@ WITH ml.full_reconcile_id IS NULL OR MAX(ml_future.id) IS NOT NULL ) + """ + return sub_query + + def _inject_line_values(self, only_empty_partner_line=False): + """ Inject report values for report_open_items_qweb_move_line. + The "only_empty_partner_line" value is used + to compute data without partner. + """ + query_inject_move_line = """ +WITH + move_lines_amount AS + ( + """ + query_inject_move_line += self._get_line_sub_query_move_lines( + only_empty_partner_line=only_empty_partner_line, + positive_balance=True + ) + query_inject_move_line += """ + UNION + """ + query_inject_move_line += self._get_line_sub_query_move_lines( + only_empty_partner_line=only_empty_partner_line, + positive_balance=False + ) + query_inject_move_line += """ ), move_lines AS ( @@ -558,6 +588,9 @@ ORDER BY self.env.cr.execute( query_inject_move_line, (self.date_at, + self.date_at, + self.id, + self.date_at, self.date_at, self.id, self.env.uid, diff --git a/account_financial_report_qweb/report/trial_balance.py b/account_financial_report_qweb/report/trial_balance.py index ecdc7637..80b30f9a 100644 --- a/account_financial_report_qweb/report/trial_balance.py +++ b/account_financial_report_qweb/report/trial_balance.py @@ -156,7 +156,9 @@ class TrialBalanceReportCompute(models.TransientModel): self.general_ledger_id = model.create( self._prepare_report_general_ledger() ) - self.general_ledger_id.compute_data_for_report() + self.general_ledger_id.compute_data_for_report( + with_line_details=False, with_partners=self.show_partner_details + ) # Compute report data self._inject_account_values()