Re: BUG #19357: PostgreSQL generates a custom plan that performsworse than the generic plan for a certain query.
| От | Pavel Stehule |
|---|---|
| Тема | Re: BUG #19357: PostgreSQL generates a custom plan that performsworse than the generic plan for a certain query. |
| Дата | |
| Msg-id | CAFj8pRBYH0u-ACv1+HXhuPPvEfC-AjY4Nar5BU7YY5+iLTW3_w@mail.gmail.com обсуждение исходный текст |
| Ответ на | Re: BUG #19357: PostgreSQL generates a custom plan that performsworse than the generic plan for a certain query. ("ZhangChi" <798604270@qq.com>) |
| Ответы |
Re: BUG #19357: PostgreSQL generates a custom plan that performsworsethan the generic plan for a certain query.
|
| Список | pgsql-bugs |
st 17. 12. 2025 v 16:17 odesílatel ZhangChi <798604270@qq.com> napsal:
Hi Greg Sabino Mullane,Thanks for your work.This is already the test case that I can simplify as much as possbile. I also generate the corresponding query plan in TEXT format.In this test case, the prepared statement (with a generic plan) is much more efficitive than the normal SELECT (with a custom plan).```SET plan_cache_mode = force_generic_plan;CREATE TABLE t0(c0 smallint) USING heap WITH (parallel_workers=852);CREATE TABLE t2(LIKE t0);CREATE TABLE t5(LIKE t0);INSERT INTO t5(c0) VALUES(1::INT8);INSERT INTO t0(c0) VALUES(1::int8);CREATE INDEX i0 ON t5(c0 NULLS FIRST);EXPLAIN (ANALYZE, FORMAT TEXT) SELECT DISTINCT t5.c0 FROM t5, t2, t0*, (SELECT ALL t2.c0 as c0 FROM t2 WHERE ((CAST(((''::text)||('[142654042,1443301405)'::int4range)) AS BOOLEAN))) LIMIT (7461843809418659830)::int8) AS subq WHERE ((t5.c0)::VARCHAR SIMILAR TO ''::text);PREPARE prepare_query (text, int4range, int8, text) AS SELECT DISTINCT t5.c0 FROM t5, t2*, t0*, (SELECT t2.c0 as c0 FROM t2 WHERE ((CAST((($1)||($2)) AS BOOLEAN))) LIMIT $3) AS subq WHERE ((t5.c0)::VARCHAR SIMILAR TO $4);EXPLAIN (ANALYZE, FORMAT TEXT) EXECUTE prepare_query('', '[142654042,1443301405)'::int4range, 7461843809418659830, '');```This is the outputs:```QUERY PLAN---------------------------------------------------------------------------------------------------------------------------------------Unique (cost=522496.96..303238953.76 rows=1 width=2) (actual time=65.267..65.311 rows=0 loops=1)-> Nested Loop (cost=522496.96..252929833.76 rows=20123648000 width=2) (actual time=65.267..65.310 rows=0 loops=1)-> Gather Merge (cost=522496.94..1384162.54 rows=7398400 width=2) (actual time=65.266..65.309 rows=0 loops=1)Workers Planned: 2Workers Launched: 2-> Sort (cost=521496.92..529203.59 rows=3082667 width=2) (actual time=21.743..21.744 rows=0 loops=3)Sort Key: t5.c0Sort Method: quicksort Memory: 25kBWorker 0: Sort Method: quicksort Memory: 25kBWorker 1: Sort Method: quicksort Memory: 25kB-> Nested Loop (cost=0.00..104956.96 rows=3082667 width=2) (actual time=21.699..21.700 rows=0 loops=3)-> Parallel Seq Scan on t0 (cost=0.00..21.33 rows=1133 width=0) (actual time=0.002..0.002 rows=0 loops=3)-> Nested Loop (cost=0.00..65.42 rows=2720 width=2) (actual time=65.088..65.089 rows=0 loops=1)-> Seq Scan on t5 (cost=0.00..1.02 rows=1 width=2) (actual time=65.088..65.088 rows=0 loops=1)Filter: (((c0)::character varying)::text ~ '^(?:)$'::text)Rows Removed by Filter: 1-> Seq Scan on t2 (cost=0.00..37.20 rows=2720 width=0) (never executed)-> Materialize (cost=0.01..78.01 rows=2720 width=0) (never executed)-> Subquery Scan on subq (cost=0.01..64.41 rows=2720 width=0) (never executed)-> Limit (cost=0.01..37.21 rows=2720 width=2) (never executed)-> Result (cost=0.01..37.21 rows=2720 width=2) (never executed)One-Time Filter: ((''::text || ('[142654042,1443301405)'::int4range)::text))::boolean-> Seq Scan on t2 t2_1 (cost=0.01..37.21 rows=2720 width=0) (never executed)Planning Time: 0.195 msJIT:Functions: 21Options: Inlining true, Optimization true, Expressions true, Deforming trueTiming: Generation 0.636 ms (Deform 0.114 ms), Inlining 34.664 ms, Optimization 18.423 ms, Emission 11.975 ms, Total 65.698 msExecution Time: 74.751 ms(29 rows)QUERY PLAN------------------------------------------------------------------------------------------------------------------------------HashAggregate (cost=30194812.07..30194812.08 rows=1 width=2) (actual time=0.008..0.009 rows=0 loops=1)Group Key: t5.c0Batches: 1 Memory Usage: 24kB-> Nested Loop (cost=0.01..25163900.07 rows=2012364800 width=2) (actual time=0.007..0.008 rows=0 loops=1)-> Nested Loop (cost=0.01..9296.07 rows=739840 width=2) (actual time=0.007..0.007 rows=0 loops=1)-> Seq Scan on t2 (cost=0.00..37.20 rows=2720 width=0) (actual time=0.007..0.007 rows=0 loops=1)-> Materialize (cost=0.01..11.55 rows=272 width=2) (never executed)-> Nested Loop (cost=0.01..10.19 rows=272 width=2) (never executed)-> Seq Scan on t5 (cost=0.00..1.02 rows=1 width=2) (never executed)Filter: (((c0)::character varying)::text ~ similar_to_escape($4))-> Limit (cost=0.01..3.73 rows=272 width=2) (never executed)-> Result (cost=0.01..37.21 rows=2720 width=2) (never executed)One-Time Filter: (($1 || ($2)::text))::boolean-> Seq Scan on t2 t2_1 (cost=0.01..37.21 rows=2720 width=0) (never executed)-> Materialize (cost=0.00..50.80 rows=2720 width=0) (never executed)-> Seq Scan on t0 (cost=0.00..37.20 rows=2720 width=0) (never executed)Planning Time: 0.110 msJIT:Functions: 15Options: Inlining true, Optimization true, Expressions true, Deforming trueTiming: Generation 0.208 ms (Deform 0.053 ms), Inlining 0.000 ms, Optimization 0.000 ms, Emission 0.000 ms, Total 0.208 msExecution Time: 0.289 ms(22 rows)```
There are brutal estimation errors - you missing ANALYZE after initialization.
When there are too big estimation errors, the planner behaviour can be not intuitive - and nobody should to expect good results
Regards
Pavel
Original
Date: 2025-12-17 22:54Subject: Re: BUG #19357: PostgreSQL generates a custom plan that performsworse than the generic plan for a certain query.Please simplify your test query as much as possible and use "text" format in your explain results; those will improve your chances of getting a useful reply. :)
В списке pgsql-bugs по дате отправления: