On Mon, Aug 15, 2022 at 8:53 AM jian he <[email protected]> wrote:
> select * from
> (
> (select 2 as v )
> union all
> (select 3 as v)
> ) as q1
> cross join lateral
> ( (select * from
> ((select 4 as v) union all
> (select 5 as v)) as q3
> )
> union all
> (select q1.v)
> ) as q2;
>
> I thought q1 will be materialized as a constant set and will be equivalent
> as select 2 union all select 3;
> Then It will have 8 (2 * 4) rows total. Then It will be like {2,3} cross
> join with {2,3,4,5}
>
> But Here the actual result(return 6 rows) feels like two separate
> queries(A,B) then union together.
> QueryA: (select 2 as v ) cross join lateral (.....)
> QueryB: (select 3 as v ) cross join lateral (.....)
> Query A 3 row + Query B 3 row. So the total is 6 rows.
>
> Then I feel a little bit confused.
>
>
Lateral is literally a FOR EACH row construct. So q2 is evaluated for the
first row in q1, then it is evaluated for the second row of q1. Which
produces 6 rows (4 from q2 literal rows plus two more by copying the
current row of q1 into a new row within q2 - twice).
CROSS JOIN here is a mis-nomer, and I personally avoid using it for that
reason. You are really doing an inner join between a single row from q1
and each and every row produced by evaluating q2 in the context of that q1
row (it's a bit easier to understand if you have a function lateral as
opposed to a subquery, but the effects are identical).
q1 INNER JOIN LATERAL AS q2 ON true
Where q2 can use the columns of q1 in producing its output.
David J.