Обсуждение: Default Inline CTE makes JOIN slower

Поиск
Список
Период
Сортировка

Default Inline CTE makes JOIN slower

От
hao li
Дата:
Hi,
I have this example query in my code

create or replace function slow_int() returns integer language sql stable 

as $$

select pg_sleep(1);

select 1;

$$;


explain analyze WITH s AS (

SELECT * FROM (values (1), (2), (3)) s(a)

),

slow_int AS (

SELECT slow_int()

)

SELECT * FROM s

JOIN slow_int ON true;


and I got this explain analyze output which execute slow_int() three times, you can see the execution time is 3s, not 1s.


Values Scan on "*VALUES*"  (cost=0.00..0.79 rows=3 width=8) (actual time=1002.468..3005.399 rows=3 loops=1)
Planning Time: 0.326 ms
Execution Time: 3005.512 ms


It happens because PG12 automatically inline CTE, and if I force it to be materialized, I can get previous execution time.



Re: Default Inline CTE makes JOIN slower

От
Pavel Stehule
Дата:
Hi

po 29. 3. 2021 v 15:39 odesílatel hao li <shell0fly@gmail.com> napsal:
Hi,
I have this example query in my code

create or replace function slow_int() returns integer language sql stable 

as $$

select pg_sleep(1);

select 1;

$$;


explain analyze WITH s AS (

SELECT * FROM (values (1), (2), (3)) s(a)

),

slow_int AS (

SELECT slow_int()

)

SELECT * FROM s

JOIN slow_int ON true;


and I got this explain analyze output which execute slow_int() three times, you can see the execution time is 3s, not 1s.


Values Scan on "*VALUES*"  (cost=0.00..0.79 rows=3 width=8) (actual time=1002.468..3005.399 rows=3 loops=1)
Planning Time: 0.326 ms
Execution Time: 3005.512 ms


It happens because PG12 automatically inline CTE, and if I force it to be materialized, I can get previous execution time.


sure. It is expected behaviour - and reason why there is new clause MATERIALIZED

Regards

Pavel