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

[FW][FIX] res_currency: add order by to _select_companies_rates query #106095

Closed

Conversation

fw-bot
Copy link
Contributor

@fw-bot fw-bot commented Nov 18, 2022

PG12 introduced an optimization for CTEs that automatically inlines
CTEs if they are only refered once in the parent query. Prior
to that CTEs were always materialized, meaning
that PG created a sort of temp table on the fly to store the result
of the CTE's evaluation.

Whereas this leads to performance improvements in general, in the particular
case of _select_companies_rates this inlining becomes a performance
bottleneck. This is because while the currency_rate CTE is
only refered once in both purchase_report and product_margin,
the Merge Join Filter cr.date_end is null or cr.date_end > ...
requires evaluating the CTE's date_end subquery twice. This, combined
with the fact that in PG12 the planner goes for a Nested Loop Join instead
of a Hash Join in PG10 makes the performances of the whole query
much worse in PG12 than in PG10. PG10 query plan vs PG12 query plan.

We can see on the PG12 Query Plan that the Merge Join Node 7 scans the CTE twice (SubPlan 1 and SubPlan 2).
An eazy solution would be to add the keyword Materialized before the CTE definition. This keyword, introduced
in PG12
, forces the materialization of the CTE, avoiding its inlining and making the PG12 plan the same as the PG10 one. Unfortunately, Materialized wasn't there in PG10 so we cannot use this solution here since some Odoo instances still run on PG10.

Instead, this PR adds an ORDER BY date_end clause at the end of the CTE. This works like an OFFSET 0
as it is kind of an optimizer fence, forcing PG to evaluate the subquery first Ordered PG12 query plan

Speedup

Test DB with 7000 purchase_order, 2666 res_currency_rate and 6 active currencies.
Purchase_report query timings in PG12, changing the number of purchase_orders

Number of POs Before PR After PR
500 2s 115ms
2000 7s 345ms
4000 13.5s 640ms
7000 23s 1.1s

Changing the number of res_currency_rate

Number of res_currency_rate Before PR After PR
200 1.7s 150ms
500 4s 270ms
1000 6.8s 488ms
2666 23s 1.1s

--
I confirm I have signed the CLA and read the PR guidelines at www.odoo.com/submit-pr

Forward-Port-Of: #98844

PG12 introduced an optimization for CTEs that automatically inlines
CTEs if they are only refered once in the parent query. Prior to that
CTEs were always materialzed, meaning that PG created a sort of temp
table on the fly to store the result of the CTE's evaluation.

Whereas this leads to performance improvements in general, in the
particular case of _select_companies_rates this inlining becomes a
performance bottleneck. This is because while the currency_rate CTE
is only refered once in both purchase_report and product_margin,
the join condition (cr.date_end is null or cr.date_end > ...)
requires evaluating the CTE's date_end subquery twice. This, combined
with the fact that in PG12 the planner goes for a Nested Loop JOIN instead
of a HASH Join in PG10 makes the performances of the whole query
much worse in PG12 than in PG10.

Adding an ORDER BY (or an OFFSET 0, the resulting plan is the same)
creates a kind of optimization fence that forces PG to evaluate the
subquery first using its own plan. This removes the need to rescan the
subquery each time the Merge JOIN filter has to be applied, which
is a good strategy in this specific situation.

The same result could be achieved by adding the keyword "MATERIALIZED"
in the CTE definition. The issue is that this keyword did not exist
in PG 10 so using it would require to check the PG version at runtime
from python.

Examples of query timings change before and after PR:

Number of POs | Before PR | After PR
      2000    |     7s    |    345ms
      7000    |     23s   |    1.1s

opw-2930578

X-original-commit: 8b7a394
@robodoo
Copy link
Contributor

robodoo commented Nov 18, 2022

@fw-bot
Copy link
Contributor Author

fw-bot commented Nov 18, 2022

This PR targets saas-15.3 and is part of the forward-port chain. Further PRs will be created up to master.

More info at https://github.com/odoo/odoo/wiki/Mergebot#forward-port

@robodoo robodoo added the forwardport This PR was created by @fw-bot label Nov 18, 2022
@C3POdoo C3POdoo added the OE the report is linked to a support ticket (opw-...) label Nov 18, 2022
@rco-odoo
Copy link
Member

@fw-bot r+

robodoo pushed a commit that referenced this pull request Nov 25, 2022
PG12 introduced an optimization for CTEs that automatically inlines
CTEs if they are only refered once in the parent query. Prior to that
CTEs were always materialzed, meaning that PG created a sort of temp
table on the fly to store the result of the CTE's evaluation.

Whereas this leads to performance improvements in general, in the
particular case of _select_companies_rates this inlining becomes a
performance bottleneck. This is because while the currency_rate CTE
is only refered once in both purchase_report and product_margin,
the join condition (cr.date_end is null or cr.date_end > ...)
requires evaluating the CTE's date_end subquery twice. This, combined
with the fact that in PG12 the planner goes for a Nested Loop JOIN instead
of a HASH Join in PG10 makes the performances of the whole query
much worse in PG12 than in PG10.

Adding an ORDER BY (or an OFFSET 0, the resulting plan is the same)
creates a kind of optimization fence that forces PG to evaluate the
subquery first using its own plan. This removes the need to rescan the
subquery each time the Merge JOIN filter has to be applied, which
is a good strategy in this specific situation.

The same result could be achieved by adding the keyword "MATERIALIZED"
in the CTE definition. The issue is that this keyword did not exist
in PG 10 so using it would require to check the PG version at runtime
from python.

Examples of query timings change before and after PR:

Number of POs | Before PR | After PR
      2000    |     7s    |    345ms
      7000    |     23s   |    1.1s

opw-2930578

closes #106095

X-original-commit: 8b7a394
Signed-off-by: Raphael Collet <rco@odoo.com>
@robodoo robodoo temporarily deployed to merge November 25, 2022 09:51 Inactive
@robodoo robodoo closed this Nov 25, 2022
@fw-bot fw-bot deleted the saas-15.3-13.0-opw-2930578-avd-2Zjr-fw branch December 9, 2022 10:47
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
forwardport This PR was created by @fw-bot OE the report is linked to a support ticket (opw-...)
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

5 participants