I found an error similar to others before ([1]) that is still persists as of head right now (0bcb3ca3b9).
CREATE TABLE t ( n INTEGER );
SELECT * FROM (VALUES (1)) t(c) LEFT JOIN t ljl1 ON true LEFT JOIN LATERAL (WITH cte AS (SELECT * FROM t WHERE t.n = ljl1.n) SELECT * FROM cte) ljl2 ON ljl1.n = 1;
ERROR: wrong varnullingrels (b 3) (expected (b)) for Var 2/1
Note that the error does **not** occur if the CTE is unwrapped like this:
SELECT * FROM (VALUES (1)) t(c) LEFT JOIN t ljl1 ON true LEFT JOIN LATERAL (SELECT * FROM t WHERE t.n = ljl1.n) ljl2 ON ljl1.n = 1;
Thanks for the report! Reproduced here. Also it can be reproduced with subquery, as long as the subquery is not pulled up.
SELECT * FROM (VALUES (1)) t(c) LEFT JOIN t ljl1 ON true LEFT JOIN LATERAL (SELECT * FROM t WHERE t.n = ljl1.n offset 0) ljl2 ON ljl1.n = 1; ERROR: wrong varnullingrels (b 3) (expected (b)) for Var 2/1
When we transform the first form of identity 3 to the second form, we've converted Pb*c to Pbc in deconstruct_distribute_oj_quals. But we neglect to consider that rel C might be a RTE_SUBQUERY and contains quals that have lateral references to B. So the B vars in such quals have wrong nulling bitmaps and we'd finally notice that when we do fix_upper_expr for the NestLoopParam expressions.
We can identify in which form of identity 3 the plan is built up by checking the relids of the B/C join's outer rel. If it's in the first form, the outer rel's relids must contain the A/B join. Otherwise it should only contain B's relid. So I'm considering that maybe we can adjust the nulling bitmap for nestloop parameters according to that.
Attached is a patch for that. Does this make sense?