On Mon, Jan 12, 2026 at 6:13 PM Robert Haas <[email protected]> wrote:
[..]
> Here's v9. Changes:
OK, so I was thinking v9 is going to be pretty slick ride, however got
some issues inside 0005 :
1) with cassert/debug builds (meson setup build --prefix=/usr/pgsql19
--buildtype=debug -Dcassert=true) I've started getting nonalways
non-deterministic failures for TPC-H Q4 and Q8. That was a somewhat
self-dissolving error (happened fresh after data load when the testing
suite was launched rapidly afterwards), so I've tracked it down to the
autoanalyze gathering stats. So if load the the whole suite of data,
do not run analyze and stay with autovacuum=off (to avoid autoanalyze)
and run the testing query suite, it identified this failure to force
NL instead of HJ in q8 but also *uncovered* runtime error in q4 that
happens with no stats
a) q4.sql (please see attached file for repro). More or less: right
after import I get a hard failure if the earlier recommended advice is
enabled (smells like a bug to me: we shouldn't get any errors even if
advice is bad). This can be solved by ANALYZE, but brought up back by
truncating pg_statistics
ERROR: unique semijoin found for relids (b 3) but not observed during planning
STATEMENT: explain (timing off, costs off, settings off, memory off)
a) q8.sql (please see attached file for demo). It is even more
bizarre, happens right after import , fixed by ANALYZE, but even
TRUNCATING pg_statistic doesnt bring back the problem. Pinpointed that
additional pg_clear_relation_stats() triggers the problem back.
2) Somewhat in default buildtype debugoptimized (plain "meson setup
build --prefix=/usr/pgsql19") I'm getting crashes with v9 in
contrib/pg_plan_advice/pgpa_planner.c:pgpa_join_path_setup line 460,
full stack trace attached.
2026-01-14 10:54:04.718 CET [97138] LOG: client backend (PID 97408)
was terminated by signal 11: Segmentation fault
2026-01-14 10:54:04.718 CET [97138] DETAIL: Failed process was
running: explain (timing off, costs off, settings off, memory off)
SELECT
s_name,
s_address
[..]
AND s_nationkey = n_nationkey
AND n_name = 'CANADA'
ORDER BY
s_name;
2026-01-14 10:54:04.718 CET [97138] LOG: terminating any other active
server processes
To me it looks like "pps" is NULL and hits "if
(pps->generate_advice_string)" because
GetPlannerGlobalExtensionState() returns NULL because
root->glob->extension_state_allocated is 0 (while planner_extension_id
is also 0). Crash is only happening for q20 and q4, till I've tried
the below fixup which seems to solve it (?) - it's just based on the
fact that all other uses of GetPlannerGlobalExtensionState() seem to
check for NULL:
- if (pps->generate_advice_string)
+ if (pps != NULL && pps->generate_advice_string)
3) Also so I went ahead runnning the full suite (without and with
ANALYZE statistics) with asan, so with CFLAGS="-O2 -g -ggdb
-fno-sanitize-recover=all -fsanitize=address" and
ASAN_OPTIONS=detect_leaks=0:abort_on_error=1:print_stacktrace=1:disable_coredump=0:strict_string_checks=1:check_initialization_order=1:strict_init_order=1:detect_stack_use_after_return=0
(the last option seem to be critical to avoid hitting max_stack_depth
issues on my gcc - XXX marker here). So it did catch previous issue,
e.g:
[..all queries running fine..]
q19.sql
q1.sql
q20.sql
AddressSanitizer:DEADLYSIGNAL
=================================================================
==153072==ERROR: AddressSanitizer: SEGV on unknown address
0x000000000008 (pc 0x7de84f7822cc bp 0x7ffda327e420 sp 0x7ffda327e130
T0)
==153072==The signal is caused by a READ memory access.
==153072==Hint: address points to the zero page.
#0 0x7de84f7822cc in pgpa_join_path_setup
../contrib/pg_plan_advice/pgpa_planner.c:460
#1 0x64bff4d5966d in add_paths_to_joinrel
../src/backend/optimizer/path/joinpath.c:180
#2 0x64bff4d60a8a in populate_joinrel_with_paths
../src/backend/optimizer/path/joinrels.c:1197
#3 0x64bff4d63377 in make_join_rel
../src/backend/optimizer/path/joinrels.c:774
[..]
but with the above fixup all seems to clean in multiple scenarios
(stats, no stats) and including basic "ninja test".
3b) XXX - marker:I was looking for a solution and apparently cfbot
farm has those options, so they should be testing it anyway. And this
brings me to a fact, that it maybe could be detected by cfbot, however
the $thread is not registered so cfbot had no chance to see what's
more there? (I'm mainly thinking about any cross-platform issues, if
any).
-J.
--
-- Q4 failure when there are not stats present
--
dbt3=# select * from pg_statistic where starelid = 'lineitem'::regclass; --
should return 0 rows (probably for others rels too)
dbt3=# explain (costs off, plan_advice) SELECT
o_orderpriority,
count(*) AS order_count
FROM
orders
WHERE
o_orderdate >= DATE '1993-07-01'
AND o_orderdate < DATE '1993-07-01' + INTERVAL '3' MONTH
AND EXISTS (
SELECT
*
FROM
lineitem
WHERE
l_orderkey = o_orderkey
AND l_commitdate < l_receiptdate
)
GROUP BY
o_orderpriority
ORDER BY
o_orderpriority;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------
GroupAggregate
Group Key: orders.o_orderpriority
-> Sort
Sort Key: orders.o_orderpriority
-> Nested Loop
-> Unique
-> Sort
Sort Key: lineitem.l_orderkey
-> Gather
Workers Planned: 2
-> HashAggregate
Group Key: lineitem.l_orderkey
-> Parallel Seq Scan on lineitem
Filter: (l_commitdate <
l_receiptdate)
-> Index Scan using pk_orders on orders
Index Cond: (o_orderkey = lineitem.l_orderkey)
Filter: ((o_orderdate >= '1993-07-01'::date) AND
(o_orderdate < '1993-10-01 00:00:00'::timestamp without time zone))
Generated Plan Advice:
JOIN_ORDER(lineitem orders)
NESTED_LOOP_PLAIN(orders)
SEQ_SCAN(lineitem)
INDEX_SCAN(orders public.pk_orders)
GATHER(lineitem)
SEMIJOIN_UNIQUE(lineitem)
NO_GATHER(orders)
(25 rows)
-- apply it
dbt3=# set pg_plan_advice.advice = 'JOIN_ORDER(lineitem orders)
NESTED_LOOP_PLAIN(orders) SEQ_SCAN(lineitem) INDEX_SCAN(orders
public.pk_orders) GATHER(lineitem) SEMIJOIN_UNIQUE(lineitem) NO_GATHER(orders)';
dbt3=# explain (costs off) SELECT
o_orderpriority,
count(*) AS order_count
FROM
orders
WHERE
o_orderdate >= DATE '1993-07-01'
AND o_orderdate < DATE '1993-07-01' + INTERVAL '3' MONTH
AND EXISTS (
SELECT
*
FROM
lineitem
WHERE
l_orderkey = o_orderkey
AND l_commitdate < l_receiptdate
)
GROUP BY
o_orderpriority
ORDER BY
o_orderpriority;
-- HERE's the ERROR
ERROR: unique semijoin found for relids (b 3) but not observed during planning
-- but without advices it works
dbt3=# set pg_plan_advice.advice = '';
SET
dbt3=# explain (costs off) SELECT
o_orderpriority,
count(*) AS order_count
FROM
orders
WHERE
o_orderdate >= DATE '1993-07-01'
AND o_orderdate < DATE '1993-07-01' + INTERVAL '3' MONTH
AND EXISTS (
SELECT
*
FROM
lineitem
WHERE
l_orderkey = o_orderkey
AND l_commitdate < l_receiptdate
)
GROUP BY
o_orderpriority
ORDER BY
o_orderpriority;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------
GroupAggregate
Group Key: orders.o_orderpriority
-> Sort
Sort Key: orders.o_orderpriority
-> Nested Loop
-> Unique
-> Sort
Sort Key: lineitem.l_orderkey
-> Gather
Workers Planned: 2
-> HashAggregate
Group Key: lineitem.l_orderkey
-> Parallel Seq Scan on lineitem
Filter: (l_commitdate <
l_receiptdate)
-> Index Scan using pk_orders on orders
Index Cond: (o_orderkey = lineitem.l_orderkey)
Filter: ((o_orderdate >= '1993-07-01'::date) AND
(o_orderdate < '1993-10-01 00:00:00'::timestamp without time zone))
(17 rows)
dbt3=#
-- now just gather stats for 1 table out of many
dbt3=# analyze lineitem ;
ANALYZE
-- ensure adivce is set properly:
dbt3=# set pg_plan_advice.advice = 'JOIN_ORDER(lineitem orders)
NESTED_LOOP_PLAIN(orders) SEQ_SCAN(lineitem) INDEX_SCAN(orders
public.pk_orders) GATHER(lineitem) SEMIJOIN_UNIQUE(lineitem) NO_GATHER(orders)';
SET
-- and it works (so only we poured in lineitem stats, right?), we still get two
failures though :
dbt3=# explain (costs off) SELECT
o_orderpriority,
count(*) AS order_count
FROM
orders
WHERE
o_orderdate >= DATE '1993-07-01'
AND o_orderdate < DATE '1993-07-01' + INTERVAL '3' MONTH
AND EXISTS (
SELECT
*
FROM
lineitem
WHERE
l_orderkey = o_orderkey
AND l_commitdate < l_receiptdate
)
GROUP BY
o_orderpriority
ORDER BY
o_orderpriority;
QUERY PLAN
------------------------------------------------------------------------------------------------------------------------------------------------
GroupAggregate
Group Key: orders.o_orderpriority
-> Sort
Sort Key: orders.o_orderpriority
-> Hash Right Semi Join
Hash Cond: (lineitem.l_orderkey = orders.o_orderkey)
-> Gather
Workers Planned: 2
-> Parallel Seq Scan on lineitem
Filter: (l_commitdate < l_receiptdate)
-> Hash
-> Index Scan using pk_orders on orders
Filter: ((o_orderdate >= '1993-07-01'::date) AND
(o_orderdate < '1993-10-01 00:00:00'::timestamp without time zone))
Supplied Plan Advice:
SEQ_SCAN(lineitem) /* matched */
INDEX_SCAN(orders public.pk_orders) /* matched */
JOIN_ORDER(lineitem orders) /* matched, conflicting */
NESTED_LOOP_PLAIN(orders) /* matched, conflicting, failed */
SEMIJOIN_UNIQUE(lineitem) /* matched, conflicting, failed */
GATHER(lineitem) /* matched */
NO_GATHER(orders) /* matched */
-- let's go back to without stats:
SET allow_system_table_mods = ON;
TRUNCATE pg_statistic;
-- and grab new psql session and let's do again (same advice):
dbt3=# set pg_plan_advice.advice = 'JOIN_ORDER(lineitem orders)
NESTED_LOOP_PLAIN(orders) SEQ_SCAN(lineitem) INDEX_SCAN(orders
public.pk_orders) GATHER(lineitem) SEMIJOIN_UNIQUE(lineitem) NO_GATHER(orders)';
SET
dbt3=# explain (costs off) SELECT
o_orderpriority,
count(*) AS order_count
FROM
orders
WHERE
o_orderdate >= DATE '1993-07-01'
AND o_orderdate < DATE '1993-07-01' + INTERVAL '3' MONTH
AND EXISTS (
SELECT
*
FROM
lineitem
WHERE
l_orderkey = o_orderkey
AND l_commitdate < l_receiptdate
)
GROUP BY
o_orderpriority
ORDER BY
o_orderpriority;
ERROR: unique semijoin found for relids (b 3) but not observed during planning
dbt3=#
-- q8 failure summary:
JOIN_ORDER(n1 region customer orders lineitem part supplier n2) /*
matched, conflicting, failed */
NESTED_LOOP_PLAIN(part) /* matched, conflicting, failed */
NESTED_LOOP_PLAIN(supplier) /* matched, conflicting, failed */
--- /tmp/plan 2026-01-14 08:03:36.360974545 +0100
+++ /tmp/planadviced 2026-01-14 08:03:36.362974547 +0100
@@ -3,8 +3,10 @@
-> Sort
Sort Key: (EXTRACT(year FROM orders.o_orderdate))
-> Nested Loop
- -> Nested Loop
- -> Nested Loop
+ -> Hash Join
+ Hash Cond: (lineitem.l_partkey = part.p_partkey)
+ -> Hash Join
+ Hash Cond: (lineitem.l_suppkey = supplier.s_suppkey)
-> Nested Loop
-> Nested Loop
-> Nested Loop
@@ -23,10 +25,10 @@
Filter: ((o_orderdate >=
'1995-01-01'::date) AND (o_orderdate <= '1996-12-31'::date))
-> Index Scan using pk_lineitem on lineitem
Index Cond: (l_orderkey =
orders.o_orderkey)
+ -> Hash
+ -> Index Scan using pk_supplier on supplier
+ -> Hash
-> Index Scan using pk_part on part
- Index Cond: (p_partkey = lineitem.l_partkey)
Filter: ((p_type)::text = 'ECONOMY ANODIZED
STEEL'::text)
- -> Index Scan using pk_supplier on supplier
- Index Cond: (s_suppkey = lineitem.l_suppkey)
-> Index Scan using pk_nation on nation n2
Index Cond: (n_nationkey = supplier.s_nationkey)
--
-- manual repro details:
--
dbt3=# explain (costs off, plan_advice) SELECT
o_year,
sum(CASE
WHEN nation = 'BRAZIL'
THEN volume
ELSE 0
END) / sum(volume) AS mkt_share
FROM (
SELECT
extract(year FROM o_orderdate) AS o_year,
l_extendedprice * (1 - l_discount) AS volume,
n2.n_name AS nation
FROM
part,
supplier,
lineitem,
orders,
customer,
nation n1,
nation n2,
region
WHERE
p_partkey = l_partkey
AND s_suppkey = l_suppkey
AND l_orderkey = o_orderkey
AND o_custkey = c_custkey
AND c_nationkey = n1.n_nationkey
AND n1.n_regionkey = r_regionkey
AND r_name = 'AMERICA'
AND s_nationkey = n2.n_nationkey
AND o_orderdate BETWEEN DATE '1995-01-01' AND DATE '1996-12-31'
AND p_type = 'ECONOMY ANODIZED STEEL'
) AS all_nations
GROUP BY
o_year
ORDER BY
o_year;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------
GroupAggregate
Group Key: (EXTRACT(year FROM orders.o_orderdate))
-> Sort
Sort Key: (EXTRACT(year FROM orders.o_orderdate))
-> Nested Loop
-> Nested Loop
-> Nested Loop
-> Nested Loop
-> Nested Loop
-> Nested Loop
-> Hash Join
Hash Cond: (n1.n_regionkey =
region.r_regionkey)
-> Seq Scan on nation n1
-> Hash
-> Seq Scan on region
Filter: (r_name
= 'AMERICA'::bpchar)
-> Bitmap Heap Scan on customer
Recheck Cond: (c_nationkey =
n1.n_nationkey)
-> Bitmap Index Scan on
customer_c_nationkey_c_custkey_idx
Index Cond:
(c_nationkey = n1.n_nationkey)
-> Index Scan using
orders_o_custkey_idx on orders
Index Cond: (o_custkey =
customer.c_custkey)
Filter: ((o_orderdate >=
'1995-01-01'::date) AND (o_orderdate <= '1996-12-31'::date))
-> Index Scan using pk_lineitem on lineitem
Index Cond: (l_orderkey =
orders.o_orderkey)
-> Index Scan using pk_part on part
Index Cond: (p_partkey = lineitem.l_partkey)
Filter: ((p_type)::text = 'ECONOMY ANODIZED
STEEL'::text)
-> Index Scan using pk_supplier on supplier
Index Cond: (s_suppkey = lineitem.l_suppkey)
-> Index Scan using pk_nation on nation n2
Index Cond: (n_nationkey = supplier.s_nationkey)
Generated Plan Advice:
JOIN_ORDER(n1 region customer orders lineitem part supplier n2)
NESTED_LOOP_PLAIN(customer orders lineitem part supplier n2)
HASH_JOIN(region)
SEQ_SCAN(n1 region)
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx)
INDEX_SCAN(orders public.orders_o_custkey_idx lineitem public.pk_lineitem
part public.pk_part supplier public.pk_supplier n2 public.pk_nation)
NO_GATHER(part supplier lineitem orders customer n1 n2 region)
-- copy paste because why not?
dbt3=# set pg_plan_advice.advice = 'JOIN_ORDER(n1 region customer orders
lineitem part supplier n2)
NESTED_LOOP_PLAIN(customer orders lineitem part supplier n2)
HASH_JOIN(region)
SEQ_SCAN(n1 region)
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx)
INDEX_SCAN(orders public.orders_o_custkey_idx lineitem public.pk_lineitem
part public.pk_part supplier public.pk_supplier n2 public.pk_nation)
NO_GATHER(part supplier lineitem orders customer n1 n2 region)';
SET
--
-- 3x failures while adapting from advice, 2x for NESTED_LOOP_PLAIN
-- causing HJ instead of NL
--
dbt3=# explain (costs off) SELECT
o_year,
sum(CASE
WHEN nation = 'BRAZIL'
THEN volume
ELSE 0
END) / sum(volume) AS mkt_share
FROM (
SELECT
extract(year FROM o_orderdate) AS o_year,
l_extendedprice * (1 - l_discount) AS volume,
n2.n_name AS nation
FROM
part,
supplier,
lineitem,
orders,
customer,
nation n1,
nation n2,
region
WHERE
p_partkey = l_partkey
AND s_suppkey = l_suppkey
AND l_orderkey = o_orderkey
AND o_custkey = c_custkey
AND c_nationkey = n1.n_nationkey
AND n1.n_regionkey = r_regionkey
AND r_name = 'AMERICA'
AND s_nationkey = n2.n_nationkey
AND o_orderdate BETWEEN DATE '1995-01-01' AND DATE '1996-12-31'
AND p_type = 'ECONOMY ANODIZED STEEL'
) AS all_nations
GROUP BY
o_year
ORDER BY
o_year;
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------
GroupAggregate
Group Key: (EXTRACT(year FROM orders.o_orderdate))
-> Sort
Sort Key: (EXTRACT(year FROM orders.o_orderdate))
-> Nested Loop
-> Hash Join
Hash Cond: (lineitem.l_partkey = part.p_partkey)
-> Hash Join
Hash Cond: (lineitem.l_suppkey = supplier.s_suppkey)
-> Nested Loop
-> Nested Loop
-> Nested Loop
-> Hash Join
Hash Cond: (n1.n_regionkey =
region.r_regionkey)
-> Seq Scan on nation n1
-> Hash
-> Seq Scan on region
Filter: (r_name
= 'AMERICA'::bpchar)
-> Bitmap Heap Scan on customer
Recheck Cond: (c_nationkey =
n1.n_nationkey)
-> Bitmap Index Scan on
customer_c_nationkey_c_custkey_idx
Index Cond:
(c_nationkey = n1.n_nationkey)
-> Index Scan using
orders_o_custkey_idx on orders
Index Cond: (o_custkey =
customer.c_custkey)
Filter: ((o_orderdate >=
'1995-01-01'::date) AND (o_orderdate <= '1996-12-31'::date))
-> Index Scan using pk_lineitem on lineitem
Index Cond: (l_orderkey =
orders.o_orderkey)
-> Hash
-> Index Scan using pk_supplier on supplier
-> Hash
-> Index Scan using pk_part on part
Filter: ((p_type)::text = 'ECONOMY ANODIZED
STEEL'::text)
-> Index Scan using pk_nation on nation n2
Index Cond: (n_nationkey = supplier.s_nationkey)
Supplied Plan Advice:
SEQ_SCAN(n1) /* matched */
SEQ_SCAN(region) /* matched */
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx) /*
matched */
INDEX_SCAN(orders public.orders_o_custkey_idx) /* matched */
INDEX_SCAN(lineitem public.pk_lineitem) /* matched */
INDEX_SCAN(part public.pk_part) /* matched */
INDEX_SCAN(supplier public.pk_supplier) /* matched */
INDEX_SCAN(n2 public.pk_nation) /* matched */
JOIN_ORDER(n1 region customer orders lineitem part supplier n2) /* matched,
conflicting, failed */
NESTED_LOOP_PLAIN(customer) /* matched, conflicting */
NESTED_LOOP_PLAIN(orders) /* matched, conflicting */
NESTED_LOOP_PLAIN(lineitem) /* matched, conflicting */
NESTED_LOOP_PLAIN(part) /* matched, conflicting, failed */
NESTED_LOOP_PLAIN(supplier) /* matched, conflicting, failed */
NESTED_LOOP_PLAIN(n2) /* matched, conflicting */
HASH_JOIN(region) /* matched, conflicting */
NO_GATHER(part) /* matched */
NO_GATHER(supplier) /* matched */
NO_GATHER(lineitem) /* matched */
NO_GATHER(orders) /* matched */
NO_GATHER(customer) /* matched */
NO_GATHER(n1) /* matched */
NO_GATHER(n2) /* matched */
NO_GATHER(region) /* matched */
(59 rows)
-- of course after manual stats gathering the advices are different:
--
dbt3=# analyze ;
ANALYZE
dbt3=# explain (costs off, plan_advice) SELECT
[..]
Generated Plan Advice:
JOIN_ORDER(n1 region customer orders lineitem supplier part n2)
NESTED_LOOP_PLAIN(customer orders lineitem n2)
HASH_JOIN(region supplier part)
SEQ_SCAN(n1 region)
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx)
INDEX_SCAN(orders public.orders_o_custkey_idx lineitem public.pk_lineitem
supplier public.pk_supplier part public.pk_part n2 public.pk_nation)
NO_GATHER(part supplier lineitem orders customer n1 n2 region)
(68 rows)
-- diff of advices:
----- JOIN_ORDER is the same (just different sort),
----- of course more in HJ less in NL advice, so the question is still why we
couldn't use the plan we generated initially
--- /tmp/no-stats 2026-01-14 10:39:27.697249882 +0100
+++ /tmp/after-stats 2026-01-14 10:39:16.224234561 +0100
@@ -1,9 +1,9 @@
Generated Plan Advice:
- JOIN_ORDER(n1 region customer orders lineitem part supplier n2)
- NESTED_LOOP_PLAIN(customer orders lineitem part supplier n2)
- HASH_JOIN(region)
+ JOIN_ORDER(n1 region customer orders lineitem supplier part n2)
+ NESTED_LOOP_PLAIN(customer orders lineitem n2)
+ HASH_JOIN(region supplier part)
SEQ_SCAN(n1 region)
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx)
INDEX_SCAN(orders public.orders_o_custkey_idx lineitem public.pk_lineitem
- part public.pk_part supplier public.pk_supplier n2 public.pk_nation)
+ supplier public.pk_supplier part public.pk_part n2 public.pk_nation)
NO_GATHER(part supplier lineitem orders customer n1 n2 region)
-- so even with TRUNCATE pg_statistics the advice is different than the initial
one ()
-- so what makes it generate so wildly different plan advice if in theory both
situation is the same?
--- /tmp/no-stats 2026-01-14 10:39:27.697249882 +0100
+++ /tmp/after-stats-after-trunc-pg_stats 2026-01-14 10:43:33.864576258
+0100
@@ -1,9 +1,9 @@
Generated Plan Advice:
- JOIN_ORDER(n1 region customer orders lineitem part supplier n2)
- NESTED_LOOP_PLAIN(customer orders lineitem part supplier n2)
- HASH_JOIN(region)
- SEQ_SCAN(n1 region)
+ JOIN_ORDER(orders (n1 region customer) lineitem supplier n2 part)
+ NESTED_LOOP_PLAIN(customer lineitem supplier part)
+ HASH_JOIN(region (customer n1 region) n2)
+ SEQ_SCAN(orders n1 region n2)
BITMAP_HEAP_SCAN(customer public.customer_c_nationkey_c_custkey_idx)
- INDEX_SCAN(orders public.orders_o_custkey_idx lineitem public.pk_lineitem
- part public.pk_part supplier public.pk_supplier n2 public.pk_nation)
- NO_GATHER(part supplier lineitem orders customer n1 n2 region)
+ INDEX_SCAN(lineitem public.pk_lineitem supplier public.pk_supplier part
+ public.pk_part)
+ GATHER((part supplier lineitem orders customer n1 n2 region))
-- so if press harder and do:
-- 1. ANALYZE; -- makes problem go away
-- 2. TRUNCATE pg_statisitc + reconnect -- problem still not reproducible
-- 3. (new)select pg_clear_relation_stats('public', relname) from pg_class
where relnamespace = 2200 and relkind = 'r';
-- the problem is AGAIN reproducible
(gdb) where
#0 pgpa_join_path_setup (root=0x578e623f2bc0, joinrel=0x578e62417018,
outerrel=0x578e6240c478, innerrel=0x578e62417220, jointype=JOIN_UNIQUE_INNER,
extra=0x7fffde048d40) at ../contrib/pg_plan_advice/pgpa_planner.c:460
#1 0x0000578e3397aa3f in add_paths_to_joinrel (root=root@entry=0x578e623f2bc0,
joinrel=joinrel@entry=0x578e62417018, outerrel=outerrel@entry=0x578e6240c478,
innerrel=innerrel@entry=0x578e62417220,
jointype=jointype@entry=JOIN_UNIQUE_INNER,
sjinfo=sjinfo@entry=0x578e62416398, restrictlist=0x578e62422b20) at
../src/backend/optimizer/path/joinpath.c:180
#2 0x0000578e3397d0b4 in populate_joinrel_with_paths
(root=root@entry=0x578e623f2bc0, rel1=rel1@entry=0x578e6240c478,
rel2=rel2@entry=0x578e6241c838, joinrel=joinrel@entry=0x578e62417018,
sjinfo=sjinfo@entry=0x578e62416398,
restrictlist=0x578e62422b20) at
../src/backend/optimizer/path/joinrels.c:1197
#3 0x0000578e3397ded8 in make_join_rel (root=root@entry=0x578e623f2bc0,
rel1=0x578e6240c478, rel1@entry=0x578e6241c838, rel2=0x578e6241c838,
rel2@entry=0x578e6240c478) at ../src/backend/optimizer/path/joinrels.c:774
#4 0x0000578e3397e0dd in make_rels_by_clause_joins (first_rel_idx=0,
other_rels=0x578e6241c058, old_rel=0x578e6241c838, root=<optimized out>) at
../src/backend/optimizer/path/joinrels.c:300
[..]
(gdb) print pps
$2 = (pgpa_planner_state *) 0x0
-- bt full:
#0 pgpa_join_path_setup (root=0x578e623f2bc0, joinrel=0x578e62417018,
outerrel=0x578e6240c478, innerrel=0x578e62417220, jointype=JOIN_UNIQUE_INNER,
extra=0x7fffde048d40) at ../contrib/pg_plan_advice/pgpa_planner.c:460
pps = 0x0
uniquerel = 0x578e62417220
pjs = <optimized out>
__func__ = "pgpa_join_path_setup"
#1 0x0000578e3397aa3f in add_paths_to_joinrel (root=root@entry=0x578e623f2bc0,
joinrel=joinrel@entry=0x578e62417018, outerrel=outerrel@entry=0x578e6240c478,
innerrel=innerrel@entry=0x578e62417220,
jointype=jointype@entry=JOIN_UNIQUE_INNER,
sjinfo=sjinfo@entry=0x578e62416398, restrictlist=0x578e62422b20) at
../src/backend/optimizer/path/joinpath.c:180
save_jointype = JOIN_UNIQUE_INNER
extra = {restrictlist = 0x578e62422b20, mergeclause_list = 0x0,
inner_unique = false, sjinfo = 0x578e62416398, semifactors = {outer_match_frac
= 0.14629113674163824, match_count = 4.7563227365296745e-310},
param_source_rels = 0x0,
pgs_mask = 393215}
mergejoin_allowed = true
lc = <optimized out>
joinrelids = 0x578e62422928
#2 0x0000578e3397d0b4 in populate_joinrel_with_paths
(root=root@entry=0x578e623f2bc0, rel1=rel1@entry=0x578e6240c478,
rel2=rel2@entry=0x578e6241c838, joinrel=joinrel@entry=0x578e62417018,
sjinfo=sjinfo@entry=0x578e62416398,
restrictlist=0x578e62422b20) at
../src/backend/optimizer/path/joinrels.c:1197
unique_rel2 = 0x578e62417220
__func__ = "populate_joinrel_with_paths"
#3 0x0000578e3397ded8 in make_join_rel (root=root@entry=0x578e623f2bc0,
rel1=0x578e6240c478, rel1@entry=0x578e6241c838, rel2=0x578e6241c838,
rel2@entry=0x578e6240c478) at ../src/backend/optimizer/path/joinrels.c:774
joinrelids = 0x578e62422910
sjinfo = 0x578e62416398
reversed = true
pushed_down_joins = 0x0
sjinfo_data = {type = T_SpecialJoinInfo, min_lefthand = 0x578e33957224
<bms_copy+52>, min_righthand = 0x578e6240ec68, syn_lefthand = 0x6,
syn_righthand = 0x578e624228f8, jointype = 865534926, ojrelid = 22414,
commute_above_l = 0x0,
commute_above_r = 0x578e623f2bc0, commute_below_l = 0x578e6240a068,
commute_below_r = 0x578e6241c838, lhs_strict = 120, semi_can_btree = 196,
semi_can_hash = 64, semi_operators = 0x578e339704c3
<get_common_eclass_indexes+83>,
semi_rhs_exprs = 0x100000000}
joinrel = 0x578e62417018
restrictlist = 0x578e62422b20
trel = <optimized out>
#4 0x0000578e3397e0dd in make_rels_by_clause_joins (first_rel_idx=0,
other_rels=0x578e6241c058, old_rel=0x578e6241c838, root=<optimized out>) at
../src/backend/optimizer/path/joinrels.c:300
other_rel = 0x578e6240c478
l__state = {l = <optimized out>, i = 0}
l = <optimized out>
#5 join_search_one_level (root=root@entry=0x578e623f2bc0, level=level@entry=3)
at ../src/backend/optimizer/path/joinrels.c:123
first_rel = 0
old_rel = 0x578e6241c838
r__state = {l = 0x578e6241c388, i = 1}
joinrels = 0x578e6241c0a0
r = <optimized out>
k = <optimized out>
__func__ = "join_search_one_level"
#6 0x0000578e33967493 in standard_join_search (root=0x578e623f2bc0,
levels_needed=4, initial_rels=<optimized out>) at
../src/backend/optimizer/path/allpaths.c:3960
lc = <optimized out>
lev = 3
rel = <optimized out>
__func__ = "standard_join_search"
#7 0x0000578e3398f596 in query_planner (root=root@entry=0x578e623f2bc0,
qp_callback=qp_callback@entry=0x578e3398fc40 <standard_qp_callback>,
qp_extra=qp_extra@entry=0x7fffde0491a0) at
../src/backend/optimizer/plan/planmain.c:297
parse = 0x578e623289f0
joinlist = 0x578e62410018
final_rel = <optimized out>
__func__ = "query_planner"
#8 0x0000578e33995166 in grouping_planner (root=root@entry=0x578e623f2bc0,
tuple_fraction=<optimized out>, tuple_fraction@entry=0,
setops=setops@entry=0x0) at ../src/backend/optimizer/plan/planner.c:1733
sort_input_targets = 0x7fffde049210
sort_input_target_parallel_safe = <optimized out>
grouping_target = <optimized out>
scanjoin_target = <optimized out>
activeWindows = <optimized out>
qp_extra = {activeWindows = 0x0, gset_data = 0x0, setop = 0x0}
sort_input_targets_contain_srfs = 0x0
have_grouping = 192
wflists = <optimized out>
gset_data = 0x0
sort_input_target = <optimized out>
grouping_targets = 0x578e3399fadd <process_sublinks_mutator+301>
grouping_target_parallel_safe = <optimized out>
scanjoin_targets = 0x578e3395bb00 <check_functions_in_node+208>
scanjoin_target_parallel_safe = <optimized out>
grouping_targets_contain_srfs = 0x578e623f2bc0
scanjoin_targets_contain_srfs = 0x578e623f8be8
scanjoin_target_same_exprs = <optimized out>
parse = 0x578e623289f0
offset_est = 0
count_est = 0
limit_tuples = -1
have_postponed_srfs = false
final_target = <optimized out>
final_targets = 0x0
final_targets_contain_srfs = 0x1
final_target_parallel_safe = <optimized out>
current_rel = <optimized out>
final_rel = <optimized out>
extra = {limit_needed = 16, limit_tuples = 0, count_est =
96269045144368, offset_est = 96268262700030}
lc = <optimized out>
__func__ = "grouping_planner"
#9 0x0000578e33997e99 in subquery_planner (glob=glob@entry=0x578e623da2d8,
parse=<optimized out>, parse@entry=0x578e623289f0,
plan_name=plan_name@entry=0x0, parent_root=parent_root@entry=0x0,
hasRecursion=hasRecursion@entry=false, tuple_fraction=0,
setops=setops@entry=0x0) at ../src/backend/optimizer/plan/planner.c:1300
root = 0x578e623f2bc0
newWithCheckOptions = <optimized out>
newHaving = <optimized out>
hasOuterJoins = <optimized out>
hasResultRTEs = <optimized out>
final_rel = <optimized out>
l = <optimized out>
#10 0x0000578e33998457 in standard_planner (parse=0x578e623289f0,
query_string=0x578e622ee808 "explain (timing off, costs off, settings off,
memory off)\nSELECT\n s_name,\n s_address\nFROM\n supplier,\n
nation\nWHERE\n s_suppkey in (\n SELECT\n", ' ' <repeats 12 times>,
"ps_suppkey\n FROM\n "..., cursorOptions=2048, boundParams=0x0,
es=0x578e623da020) at ../src/backend/optimizer/plan/planner.c:517
result = <optimized out>
glob = 0x578e623da2d8
tuple_fraction = 0
root = <optimized out>
final_rel = <optimized out>
best_path = <optimized out>
top_plan = <optimized out>
lp = <optimized out>
lr = <optimized out>
#11 0x0000578e33998a55 in planner (parse=parse@entry=0x578e623289f0,
query_string=query_string@entry=0x578e622ee808 "explain (timing off, costs
off, settings off, memory off)\nSELECT\n s_name,\n s_address\nFROM\n
supplier,\n nation\nWHERE\n s_suppkey in (\n SELECT\n", ' '
<repeats 12 times>, "ps_suppkey\n FROM\n "...,
cursorOptions=cursorOptions@entry=2048, boundParams=boundParams@entry=0x0,
es=es@entry=0x578e623da020) at ../src/backend/optimizer/plan/planner.c:324
result = <optimized out>
#12 0x0000578e33a98036 in pg_plan_query
(querytree=querytree@entry=0x578e623289f0,
query_string=query_string@entry=0x578e622ee808 "explain (timing off, costs
off, settings off, memory off)\nSELECT\n s_name,\n s_address\nFROM\n
supplier,\n nation\nWHERE\n s_suppkey in (\n SELECT\n", ' '
<repeats 12 times>, "ps_suppkey\n FROM\n "...,
cursorOptions=cursorOptions@entry=2048, boundParams=boundParams@entry=0x0,
es=es@entry=0x578e623da020) at ../src/backend/tcop/postgres.c:905
plan = <optimized out>
#13 0x0000578e33893658 in standard_ExplainOneQuery (query=0x578e623289f0,
cursorOptions=2048, into=0x0, es=0x578e623da020,
queryString=0x578e622ee808 "explain (timing off, costs off, settings off,
memory off)\nSELECT\n s_name,\n s_address\nFROM\n supplier,\n
nation\nWHERE\n s_suppkey in (\n SELECT\n", ' ' <repeats 12 times>,
"ps_suppkey\n FROM\n "..., params=0x0, queryEnv=0x0) at
../src/backend/commands/explain.c:354
plan = <optimized out>
planstart = <optimized out>
planduration = {ticks = 0}
bufusage_start = {shared_blks_hit = 96268269601760, shared_blks_read =
0, shared_blks_dirtied = 96269045144368, shared_blks_written = 96268264941309,
local_blks_hit = 96269045144368, local_blks_read = 138096393063832,
local_blks_dirtied = 33239, local_blks_written =
-4160345130049447168, temp_blks_read = 138096393063832, temp_blks_written = 2,
shared_blk_read_time = {ticks = 0}, shared_blk_write_time = {ticks =
96268264941453}, local_blk_read_time = {
ticks = 0}, local_blk_write_time = {ticks = 96268260536182},
temp_blk_read_time = {ticks = 142605799162327}, temp_blk_write_time = {ticks =
-4160345130049447168}}
bufusage = {shared_blks_hit = 12542, shared_blks_read = 778195385,
shared_blks_dirtied = 140736918230349, shared_blks_written = 140736918230360,
local_blks_hit = 1024, local_blks_read = 96269043933040, local_blks_dirtied =
140733193388032,
local_blks_written = 138096083468288, temp_blks_read =
96269044451824, temp_blks_written = 610751276906, shared_blk_read_time = {ticks
= 0}, shared_blk_write_time = {ticks = 0}, local_blk_read_time = {ticks = 0},
local_blk_write_time = {
ticks = 96269045178368}, temp_blk_read_time = {ticks =
96269044217344}, temp_blk_write_time = {ticks = -4160345130049447168}}
mem_counters = {nblocks = 0, freechunks = 0, totalspace =
96269044453464, freespace = 138096393063832}
planner_ctx = 0x0
saved_ctx = 0x0
#14 0x0000578e33893834 in ExplainOneQuery (query=<optimized out>,
cursorOptions=<optimized out>, into=<optimized out>, es=<optimized out>,
pstate=<optimized out>, params=<optimized out>) at
../src/backend/commands/explain.c:310
No locals.
#15 0x0000578e3389392d in ExplainQuery (pstate=0x578e622aa208,
stmt=0x578e62328850, params=0x0, dest=0x578e622aa180) at
../src/backend/commands/explain.c:224
l__state = {l = <optimized out>, i = 0}
l = 0x578e6231a560
es = 0x578e623da020
tstate = <optimized out>
jstate = <optimized out>
query = <optimized out>
rewritten = 0x578e6231a548
#16 0x0000578e33a9db1d in standard_ProcessUtility (pstmt=0x578e623288e8,
queryString=0x578e622ee808 "explain (timing off, costs off, settings off,
memory off)\nSELECT\n s_name,\n s_address\nFROM\n supplier,\n
nation\nWHERE\n s_suppkey in (\n SELECT\n", ' ' <repeats 12 times>,
"ps_suppkey\n FROM\n "..., readOnlyTree=<optimized out>,
context=PROCESS_UTILITY_TOPLEVEL, params=0x0, queryEnv=0x0,
dest=0x578e622aa180, qc=0x7fffde049730) at ../src/backend/tcop/utility.c:868
parsetree = 0x578e62328850
isTopLevel = <optimized out>
isAtomicContext = false
pstate = 0x578e622aa208
readonly_flags = <optimized out>
__func__ = "standard_ProcessUtility"
#17 0x0000578e33a9be1f in PortalRunUtility (portal=portal@entry=0x578e62373158,
pstmt=0x578e623288e8, isTopLevel=isTopLevel@entry=true,
setHoldSnapshot=setHoldSnapshot@entry=true, dest=dest@entry=0x578e622aa180,
qc=qc@entry=0x7fffde049730)
at ../src/backend/tcop/pquery.c:1148
No locals.
#18 0x0000578e33a9c1ef in FillPortalStore (portal=portal@entry=0x578e62373158,
isTopLevel=isTopLevel@entry=true) at ../src/backend/tcop/pquery.c:1021
treceiver = 0x578e622aa180
qc = {commandTag = CMDTAG_UNKNOWN, nprocessed = 0}
__func__ = "FillPortalStore"
#19 0x0000578e33a9c51d in PortalRun (portal=portal@entry=0x578e62373158,
count=count@entry=9223372036854775807, isTopLevel=isTopLevel@entry=true,
dest=dest@entry=0x578e623dd430, altdest=altdest@entry=0x578e623dd430,
qc=qc@entry=0x7fffde049920)
at ../src/backend/tcop/pquery.c:755
_save_exception_stack = 0x7fffde049be0
_save_context_stack = 0x0
_local_sigjmp_buf = {{__jmpbuf = {96269044756824, 6410279360078897790,
140736918231328, 96269045191728, 0, 96269044451488, 582824112891978366,
6410100202314097278}, __mask_was_saved = 0, __saved_mask = {__val =
{96268265301077, 96268266004569,
96269044765032, 96268266004569, 96269044756824, 96268266004569,
1, 1, 0, 96269044451488, 96268265161652, 96268269602176, 96268263734393,
96269044756824, 96268265159153, 2}}}}
_do_rethrow = <optimized out>
result = <optimized out>
nprocessed = <optimized out>
saveTopTransactionResourceOwner = 0x578e6232e180
saveTopTransactionContext = 0x578e62385170
saveActivePortal = 0x0
saveResourceOwner = 0x578e6232e180
savePortalContext = 0x0
saveMemoryContext = 0x578e62385170
__func__ = "PortalRun"
#20 0x0000578e33a98501 in exec_simple_query (
query_string=0x578e622ee808 "explain (timing off, costs off, settings off,
memory off)\nSELECT\n s_name,\n s_address\nFROM\n supplier,\n
nation\nWHERE\n s_suppkey in (\n SELECT\n", ' ' <repeats 12 times>,
"ps_suppkey\n FROM\n "...) at ../src/backend/tcop/postgres.c:1279