Joins with LATERAL
Derived Tables
A derived table defined with the LATERAL
keyword is called a lateral derived table.If a derived table is defined as lateral, then it is allowed to refer to other tables in the same FROM
clause, but only those declared before it in the FROM
clause.
/* select customers with their last order date and number */
select c.name, ox.order_date as last_order, ox.number
from customer c
left join LATERAL (
select first 1 o.order_date, o.number
from orders o
where o.id_customer = c.id
order by o.ORDER_DATE desc
) as ox on true
--
select dt.population, dt.city_name, c.country_name
from (select distinct country_name from cities) AS c
cross join LATERAL (
select first 1 city_name, population
from cities
where cities.country_name = c.country_name
order by population desc
) AS dt;
--
select salespeople.name,
max_sale.amount,
customer_of_max_sale.customer_name
from salespeople,
LATERAL ( select max(amount) as amount
from all_sales
where all_sales.salesperson_id = salespeople.id
) as max_sale,
LATERAL ( select customer_name
from all_sales
where all_sales.salesperson_id = salespeople.id
and all_sales.amount = max_sale.amount
) as customer_of_max_sale;