Re: Very slow query performance when using CTE

2025-04-01 Thread Tom Lane
Chris Joysn  writes:
> I have an issue when using CTEs. A query, which consists of multiple CTEs,
> runs usually rather fast (~5s on my environment). But it turned out that
> using one CTE can lead to execution times of up to one minute.
> That CTE is used two times within the query.

Try labeling that CTE as NOT MATERIALIZED.

regards, tom lane




Very slow query performance when using CTE

2025-04-01 Thread Chris Joysn
Hello,
I have an issue when using CTEs. A query, which consists of multiple CTEs,
runs usually rather fast (~5s on my environment). But it turned out that
using one CTE can lead to execution times of up to one minute.
That CTE is used two times within the query. In the CTE there are 2600
rows, compared to results of the other CTEs its a fraction of the data.
When replacing this CTE and use the original table instead in the jions,
the query performs nicely.
However, it is not always like this. Running the same query on a almost
same set of data, quantity wise, may give indeed good performance when
using that CTE.
This is the slow performing query using CTE:
https://explain.dalibo.com/plan/45ce86d9cfge14c7
And this is the fast performing query without that CTE:
https://explain.dalibo.com/plan/4abgc4773gg349b4

The query runs on the very same environment and data.
What can be the issue here and how can I address it?


Re: Very slow query performance when using CTE

2025-04-01 Thread Renan Alves Fonseca
Chris Joysn  writes:

> Hello,
> I have an issue when using CTEs. A query, which consists of multiple CTEs, 
> runs usually rather fast (~5s on my
> environment). But it turned out that using one CTE can lead to execution 
> times of up to one minute.
> That CTE is used two times within the query. In the CTE there are 2600 rows, 
> compared to results of the other CTEs its a
> fraction of the data.
> When replacing this CTE and use the original table instead in the jions, the 
> query performs nicely.
> However, it is not always like this. Running the same query on a almost same 
> set of data, quantity wise, may give indeed
> good performance when using that CTE.
> This is the slow performing query using CTE: 
> https://explain.dalibo.com/plan/45ce86d9cfge14c7
> And this is the fast performing query without that CTE: 
> https://explain.dalibo.com/plan/4abgc4773gg349b4
>
> The query runs on the very same environment and data.
> What can be the issue here and how can I address it?


Hi,

the planner gets really bad estimates on the number of rows that the
first two CTE return. It is the same situation in both queries. It is
just an accident that one of them works fine.

We need to understand why these estimates are wrong. The protocol to fix
this kind of issues is to apply ANALYZE so that the statistics get
update. You can try that, but my guess is that we are dealing with a
generic plan here. So, try to replace the value of $simRunId by the
actual value and see if the plan changes.

Best regards,
Renan