with stg_xedotcom__exchange_rates as ( select * from {{ ref("stg_xedotcom__exchange_rates") }} ), -- CTEs for projecting forwards most_recent_xe_date_per_curr_pair as ( select from_currency, to_currency, max(rate_date_utc) as most_recent_date_utc from stg_xedotcom__exchange_rates group by 1, 2 ), last_xe_rate_per_curr_pair as ( select xe.from_currency, xe.to_currency, xe.rate from stg_xedotcom__exchange_rates xe inner join most_recent_xe_date_per_curr_pair recent on xe.from_currency = recent.from_currency and xe.to_currency = recent.to_currency and xe.rate_date_utc = recent.most_recent_date_utc ), future_dates as ( select date_trunc('day', day_series)::date as future_date from generate_series ( ( select max(most_recent_date_utc) from most_recent_xe_date_per_curr_pair )::timestamp, ( select max(most_recent_date_utc) from most_recent_xe_date_per_curr_pair )::timestamp + interval '3 years', '1 day'::interval ) day_series ), projected_future_rates as ( select concat( last_rate.from_currency, last_rate.to_currency, future_dates.future_date, 'inferred', 'forecast' ) as id_exchange_rate, last_rate.from_currency, last_rate.to_currency, last_rate.rate, future_dates.future_date as rate_date_utc, 'inferred' as source, 'forecast' as rate_version, now() as updated_at_utc from future_dates future_dates cross join last_xe_rate_per_curr_pair last_rate ), oldest_xe_date_per_curr_pair as ( select from_currency, to_currency, max(rate_date_utc) as oldest_date_utc from stg_xedotcom__exchange_rates group by 1, 2 ), first_xe_rate_per_curr_pair as ( select xe.from_currency, xe.to_currency, xe.rate from stg_xedotcom__exchange_rates xe inner join oldest_xe_date_per_curr_pair recent on xe.from_currency = recent.from_currency and xe.to_currency = recent.to_currency and xe.rate_date_utc = recent.oldest_date_utc ) -- here we union actual stuff, future projected stuff and past assumed stuff select concat( xe.from_currency, xe.to_currency, xe.rate_date_utc, 'xedotcom', 'actual' ) as id_exchange_rate, -- the id from staging is not useful here because dimensionality is different: here we have rate_source and rate_version xe.from_currency, xe.to_currency, xe.rate, xe.rate_date_utc, 'xedotcom' as source, 'actual' as rate_version, xe.dwh_extracted_at_utc as updated_at_utc from stg_xedotcom__exchange_rates xe union select fu.id_exchange_rate, fu.from_currency, fu.to_currency, fu.rate, fu.rate_date_utc, fu.source, fu.rate_version, fu.updated_at_utc from projected_future_rates fu