with stg_core__price_plan_to_user as ( select * from {{ ref("stg_core__price_plan_to_user") }} ), stg_core__price_plan_charged_by_type as ( select * from {{ ref("stg_core__price_plan_charged_by_type") }} ), latest_price_plan_id_by_host as ( select id_user_host, max(id_price_plan) as latest_id_price_plan from {{ ref("stg_core__price_plan_to_user") }} group by id_user_host ) select pp.id_price_plan, pp.id_user_host, ppt.price_plan_charged_by_type, pp.start_at_utc, pp.start_date_utc, coalesce(pp.end_at_utc, '2099-12-31 23:59:59') as end_at_utc, cast(coalesce(pp.end_at_utc, '2099-12-31 23:59:59') as date) end_date_utc, -- active plans have null as an end date, which is very elegant, but a PITA for -- joining. Hence, we just put a date superlong in the future. If you are in -- 2098... hi, make sure to push this :) case when pp.id_price_plan = lpp.latest_id_price_plan then true else false end as is_latest_price_plan_for_host, pp.booking_fee_local, pp.listing_fee_local, pp.support_fee_local, pp.tax_percentage, pp.minimum_billable_listings, pp.minimum_monthly_listing_fee_local, pp.created_at_utc, pp.created_date_utc, pp.updated_at_utc, pp.updated_date_utc, pp.dwh_extracted_at_utc from stg_core__price_plan_to_user pp left join stg_core__price_plan_charged_by_type ppt on pp.id_price_plan_charged_by_type = ppt.id_price_plan_charged_by_type left join latest_price_plan_id_by_host lpp on lpp.latest_id_price_plan = pp.id_price_plan