with int_mtd_aggregated_metrics as ( select * from {{ ref("int_mtd_aggregated_metrics") }} m where dimension = 'by_deal' and include_in_account_reporting = true ), int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}), int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}), daily_deal_lifecycle as (select * from {{ ref("int_kpis__lifecycle_daily_deal") }}), int_kpis__dimension_daily_accommodation as ( select * from {{ ref("int_kpis__dimension_daily_accommodation") }} ) select -- PRIMARY KEY -- m.date, m.dimension_value as id_deal, m.metric, -- TIME ATTRIBUTES -- m.year, m.month, m.day, m.is_end_of_month, m.is_current_month, m.is_end_of_month_or_yesterday, m.first_day_month, -- MAIN DEAL ATTRIBUTES -- m.dimension_value || '-' || coalesce(ikdd.main_deal_name, '') as deal, coalesce( dda.active_accommodations_per_deal_segmentation, 'UNSET' ) as active_accommodations_per_deal_segmentation, ikdd.main_billing_country_iso_3_per_deal, -- HUBSPOT ATTRIBUTES -- hd.account_manager, -- DEAL BUSINESS SCOPE case when ikdd.client_type = 'API' then 'API' when ikdd.client_type = 'PLATFORM' then case when ikdd.id_deal is not null and m.date >= ikdd.min_user_in_new_dash_since_date_utc then 'New Dash' else 'Old Dash' end else 'UNSET' end as business_scope, -- DEAL LIFECYCLE -- daily_deal_lifecycle.deal_lifecycle_state, -- METRIC VALUES AND DISPLAY -- m.order_by, m.number_format, -- Force 0 if null to avoid nulls in the report coalesce(m.value, 0) as value, coalesce(m.previous_year_value, 0) as previous_year_value, m.relative_increment, m.relative_increment_with_sign_format, m.display_exclusion from int_mtd_aggregated_metrics m left join int_kpis__dimension_deals ikdd on m.dimension_value = ikdd.id_deal left join int_hubspot__deal hd on m.dimension_value = hd.id_deal left join daily_deal_lifecycle on m.date = daily_deal_lifecycle.date and m.dimension_value = daily_deal_lifecycle.id_deal left join int_kpis__dimension_daily_accommodation as dda on m.date = dda.date and m.dimension_value = dda.id_deal where -- Only keep data for the last 24 months m.first_day_month + interval '24 months' >= date_trunc('month', current_date) and ( -- Display all accounts that have not churned hd.cancellation_date_utc is null -- Display historical information for accounts that have churned. This includes -- any data equal or prior to 3 months after the account has churned. or m.first_day_month <= date_trunc('month', hd.cancellation_date_utc) + interval '3 months' )