How Lateral Works in Postgres ?

In PostgreSQL, when you use LATERAL in a join and do not explicitly mention an ON condition, the join still happens because of the nature of how LATERAL works. Here's how it functions:

Implicit Join Condition with LATERAL

  • When you use LATERAL, the subquery is evaluated for each row of the left table in the context of that row.

  • Unlike a typical JOIN where an ON condition specifies how to combine rows from two tables, LATERAL inherently operates by re-evaluating the subquery for each row of the left table.

  • The absence of an ON condition essentially means the join is unconditional: every row from the left table contributes rows from the subquery.

    Default Behavior When ON Is Not Specified

    1. Unconditional Join: When ON TRUE or no ON clause is provided, the subquery will be executed for every row from the left table, and the results will be included in the final output.

      Example:

       SELECT lt.id, asg_detail
       FROM leftTable lt
       LEFT JOIN LATERAL (
           SELECT asg_obj::jsonb AS asg_detail
           FROM jsonb_array_elements(lt.assignment_details::jsonb) asg_obj
       ) AS asg_detail ON TRUE;
      
      • Here, ON TRUE (or omitting the ON condition) means there is no filtering or matching condition. All rows produced by the subquery are included for each row in leftTable.
    2. One-to-Many Relationship:

      • If the subquery produces multiple rows for a single row in leftTable, all those rows will be included in the result set.

      • If the subquery produces no rows, a NULL will be included in place of the subquery's output (because it's a LEFT JOIN).

    3. Behavior Without Explicit ON: PostgreSQL automatically assumes ON TRUE when no condition is provided. This is why the join works even when you don’t explicitly specify an ON condition.

Why ON TRUE Works in This Case

In this query:

SELECT DISTINCT (asg_detail ->> 'id')
FROM leftTable lt
LEFT JOIN LATERAL (
    SELECT asg_obj::jsonb AS asg_detail
    FROM jsonb_array_elements(lt.assignment_details::jsonb) asg_obj
) AS asg_detail ON TRUE;
  • No Explicit Join Condition: There is no ON condition beyond ON TRUE, meaning every row from the subquery (asg_detail) is "joined" to the corresponding row from leftTable without filtering.

  • The LATERAL subquery uses lt.assignment_details (a column from leftTable), which ties the subquery to the context of the specific row being processed.

When You Might Need an Explicit ON Condition

If you need to restrict the results from the subquery for specific rows based on additional conditions, you can include an explicit ON clause.

Example:

SELECT DISTINCT (asg_detail ->> 'id')
FROM leftTable lt
LEFT JOIN LATERAL (
    SELECT asg_obj::jsonb AS asg_detail
    FROM jsonb_array_elements(lt.assignment_details::jsonb) asg_obj
) AS asg_detail ON asg_detail ->> 'status' = 'active';

Here, the ON condition filters the results of the join to include only rows where the status field in asg_detail is 'active'.

Example:
Data in leftTable:

idassignment_details
1[{"id": "101", "name": "Task A"}, {"id": "102", "name": "Task B"}]
2[{"id": "103", "name": "Task C"}]

SELECT lt.id, asg_detail->>'id'
                    FROM leftTable lt
                    LEFT JOIN LATERAL
                    (SELECT asg_obj::jsonb AS asg_detail
                    FROM jsonb_array_elements(lt.assignment_details::jsonb) asg_obj)
                    AS asg_detail ON TRUE

Final Output of above query:

id (from leftTable)asg_detail (from subquery)
1{"id": "101", "name": "Task A"}
1{"id": "102", "name": "Task B"}
2{"id": "103", "name": "Task C"}

Summary

  • When no ON condition is provided in a LATERAL join, PostgreSQL implicitly uses ON TRUE, which means every row from the left table is combined with every output row from the LATERAL subquery.

  • LATERAL ensures the subquery is tied to the current row of the left table, making explicit join conditions optional unless further filtering is required.