diff --git a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql index 30f2cfc..5964e38 100644 --- a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql @@ -1,548 +1,352 @@ --- HubSpot stage for live deals -{% set live_stage = "Live" %} {% set churned_state = "05-Churning" %} - -{{ config(materialized="table", unique_key=["date", "id_deal"]) }} +{% set time_window_aggregations = [ + { + "time_window_name": "All History", + "preceeding_from": 0, + "preceeding_to": 1, + "include_all_history": True, + }, + { + "time_window_name": "Previous 12 months", + "preceeding_from": 12, + "preceeding_to": 1, + "include_all_history": False, + }, + { + "time_window_name": "Previous 6 months", + "preceeding_from": 6, + "preceeding_to": 1, + "include_all_history": False, + }, + { + "time_window_name": "Previous 3 months", + "preceeding_from": 3, + "preceeding_to": 1, + "include_all_history": False, + }, + { + "time_window_name": "Previous month", + "preceeding_from": 1, + "preceeding_to": 1, + "include_all_history": False, + }, +] %} +{{ config(materialized="table", unique_key=["date", "id_deal", "time_window"]) }} with - int_monthly_aggregated_metrics_history_by_deal as ( - select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} - ), + int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}), int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}), - metric_aggregation_all_history as ( - select - date, - id_deal, - client_type, - business_scope, - main_deal_name, - has_active_pms, - active_pms_list, - active_accommodations_per_deal_segmentation, - main_billing_country_iso_3_per_deal, - deal_lifecycle_state, - 'All History' as time_window, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "min", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "max", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "created_bookings", "sum", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "listings_booked_in_month", "avg", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_revenue_in_gbp", "sum", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_guest_payments_in_gbp", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_operator_net_fees_in_gbp", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_waiver_paid_back_to_host_in_gbp", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_amount_paid_in_gbp", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_payment_count", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_in_gbp", "sum", "id_deal", "date", "", 1, True - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_post_resolutions_in_gbp", - "sum", - "id_deal", - "date", - "", - 1, - True, - ) - }} - from int_monthly_aggregated_metrics_history_by_deal + int_kpis__lifecycle_daily_deal as ( + select * from {{ ref("int_kpis__lifecycle_daily_deal") }} ), - metric_aggregation_previous_12_months as ( - select - date, - id_deal, - client_type, - business_scope, - main_deal_name, - has_active_pms, - active_pms_list, - active_accommodations_per_deal_segmentation, - main_billing_country_iso_3_per_deal, - deal_lifecycle_state, - 'Previous 12 months' as time_window, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "min", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "max", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "created_bookings", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "listings_booked_in_month", "avg", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_revenue_in_gbp", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_guest_payments_in_gbp", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_waiver_paid_back_to_host_in_gbp", - "sum", - "id_deal", - "date", - 12, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_amount_paid_in_gbp", - "sum", - "id_deal", - "date", - 12, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_payment_count", - "sum", - "id_deal", - "date", - 12, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_in_gbp", "sum", "id_deal", "date", 12, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_post_resolutions_in_gbp", - "sum", - "id_deal", - "date", - 12, - 1, - ) - }} - - from int_monthly_aggregated_metrics_history_by_deal + int_kpis__dimension_daily_accommodation as ( + select * from {{ ref("int_kpis__dimension_daily_accommodation") }} ), - metric_aggregation_previous_6_months as ( - select - date, - id_deal, - client_type, - business_scope, - main_deal_name, - has_active_pms, - active_pms_list, - active_accommodations_per_deal_segmentation, - main_billing_country_iso_3_per_deal, - deal_lifecycle_state, - 'Previous 6 months' as time_window, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "min", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "max", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "created_bookings", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "listings_booked_in_month", "avg", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_revenue_in_gbp", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_guest_payments_in_gbp", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_waiver_paid_back_to_host_in_gbp", - "sum", - "id_deal", - "date", - 6, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_amount_paid_in_gbp", - "sum", - "id_deal", - "date", - 6, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_payment_count", - "sum", - "id_deal", - "date", - 6, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_in_gbp", "sum", "id_deal", "date", 6, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_post_resolutions_in_gbp", - "sum", - "id_deal", - "date", - 6, - 1, - ) - }} - - from int_monthly_aggregated_metrics_history_by_deal + int_kpis__agg_dates_main_kpis as ( + select * + from {{ ref("int_kpis__agg_dates_main_kpis") }} + where + dimension in ('by_deal') + and dimension_value <> 'UNSET' + and is_end_of_month = true ), - metric_aggregation_previous_3_months as ( - select - date, - id_deal, - client_type, - business_scope, - main_deal_name, - has_active_pms, - active_pms_list, - active_accommodations_per_deal_segmentation, - main_billing_country_iso_3_per_deal, - deal_lifecycle_state, - 'Previous 3 months' as time_window, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "min", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "max", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "created_bookings", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "listings_booked_in_month", "avg", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_revenue_in_gbp", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_guest_payments_in_gbp", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_waiver_paid_back_to_host_in_gbp", - "sum", - "id_deal", - "date", - 3, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_amount_paid_in_gbp", - "sum", - "id_deal", - "date", - 3, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_payment_count", - "sum", - "id_deal", - "date", - 3, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_in_gbp", "sum", "id_deal", "date", 3, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_post_resolutions_in_gbp", - "sum", - "id_deal", - "date", - 3, - 1, - ) - }} - - from int_monthly_aggregated_metrics_history_by_deal + created_bookings as ( + select * + from {{ ref("int_kpis__agg_monthly_created_bookings") }} + where dimension in ('by_deal') and dimension_value <> 'UNSET' ), - metric_aggregation_previous_1_month as ( + listings as ( + select * + from {{ ref("int_kpis__agg_daily_listings") }} + where + dimension in ('by_deal') + and dimension_value <> 'UNSET' + and is_end_of_month = true + ), + total_and_retained_revenue as ( + select * + from {{ ref("int_kpis__agg_monthly_total_and_retained_revenue") }} + where dimension in ('by_deal') and dimension_value <> 'UNSET' + ), + guest_payments as ( + select * + from {{ ref("int_kpis__agg_monthly_guest_payments") }} + where dimension in ('by_deal') and dimension_value <> 'UNSET' + ), + invoiced_revenue as ( + select * + from {{ ref("int_kpis__agg_monthly_invoiced_revenue") }} + where dimension in ('by_deal') and dimension_value <> 'UNSET' + ), + host_resolutions as ( + select * + from {{ ref("int_kpis__agg_monthly_host_resolutions") }} + where dimension in ('by_deal') and dimension_value <> 'UNSET' + ), + deal_history_from_previous_months as ( select - date, - id_deal, - client_type, - business_scope, - main_deal_name, - has_active_pms, - active_pms_list, - active_accommodations_per_deal_segmentation, - main_billing_country_iso_3_per_deal, - deal_lifecycle_state, - 'Previous month' as time_window, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "min", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "date", "max", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "created_bookings", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "listings_booked_in_month", "avg", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_revenue_in_gbp", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "total_guest_payments_in_gbp", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_apis_net_fees_in_gbp", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_waiver_paid_back_to_host_in_gbp", - "sum", - "id_deal", - "date", - 1, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_amount_paid_in_gbp", - "sum", - "id_deal", - "date", - 1, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "xero_host_resolution_payment_count", - "sum", - "id_deal", - "date", - 1, - 1, - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_in_gbp", "sum", "id_deal", "date", 1, 1 - ) - }}, - {{ - calculate_aggregation_between_preceeding_x_and_y( - "revenue_retained_post_resolutions_in_gbp", - "sum", - "id_deal", - "date", - 1, - 1, - ) - }} - - from int_monthly_aggregated_metrics_history_by_deal + d.year, + d.month, + d.date, + date_trunc('month', d.date)::date as first_day_month, + -- DEAL STATIC ATTRIBUTES -- + ikdd.id_deal, + ikdd.client_type, + ikdd.main_deal_name, + ikdd.has_active_pms, + ikdd.active_pms_list, + ikdd.main_billing_country_iso_3_per_deal, + -- DEAL LIFECYCLE -- + deal_lifecycle.deal_lifecycle_state, + -- ACTIVE ACCOMMODATIONS SEGMENTATION -- + coalesce( + dda.active_accommodations_per_deal_segmentation, 'UNSET' + ) as active_accommodations_per_deal_segmentation, + -- 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 d.date >= ikdd.min_user_in_new_dash_since_date_utc + then 'New Dash' + else 'Old Dash' + end + else 'UNSET' + end as business_scope, + -- METRICS -- + coalesce( + total_and_retained_revenue.total_revenue_in_gbp, 0 + ) as total_revenue_in_gbp, + coalesce( + total_and_retained_revenue.revenue_retained_in_gbp, 0 + ) as revenue_retained_in_gbp, + coalesce( + total_and_retained_revenue.revenue_retained_post_resolutions_in_gbp, 0 + ) as revenue_retained_post_resolutions_in_gbp, + coalesce( + guest_payments.total_guest_payments_in_gbp, 0 + ) as total_guest_payments_in_gbp, + coalesce( + invoiced_revenue.xero_operator_net_fees_in_gbp, 0 + ) as xero_operator_net_fees_in_gbp, + coalesce( + invoiced_revenue.xero_apis_net_fees_in_gbp, 0 + ) as xero_apis_net_fees_in_gbp, + coalesce( + invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0 + ) as xero_waiver_paid_back_to_host_in_gbp, + coalesce( + host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0 + ) as xero_host_resolution_amount_paid_in_gbp, + coalesce( + host_resolutions.xero_host_resolution_payment_count, 0 + ) as xero_host_resolution_payment_count, + coalesce(created_bookings.created_bookings, 0) as created_bookings, + listings.listings_booked_in_month + from int_kpis__agg_dates_main_kpis d + left join int_kpis__dimension_deals ikdd on d.dimension_value = ikdd.id_deal + left join + int_kpis__dimension_daily_accommodation as dda + on d.date = dda.date + and d.dimension_value = dda.id_deal + left join + int_kpis__lifecycle_daily_deal deal_lifecycle + on d.date = deal_lifecycle.date + and d.dimension_value = deal_lifecycle.id_deal + left join + created_bookings + on d.date = created_bookings.end_date + and d.dimension_value = created_bookings.dimension_value + left join + listings + on d.date = listings.date + and d.dimension_value = listings.dimension_value + left join + total_and_retained_revenue + on d.date = total_and_retained_revenue.end_date + and d.dimension_value = total_and_retained_revenue.dimension_value + left join + guest_payments + on d.date = guest_payments.end_date + and d.dimension_value = guest_payments.dimension_value + left join + invoiced_revenue + on d.date = invoiced_revenue.end_date + and d.dimension_value = invoiced_revenue.dimension_value + left join + host_resolutions + on d.date = host_resolutions.end_date + and d.dimension_value = host_resolutions.dimension_value ), metric_aggregation_by_deal as ( - select * - from metric_aggregation_all_history - union all - select * - from metric_aggregation_previous_12_months - union all - select * - from metric_aggregation_previous_6_months - union all - select * - from metric_aggregation_previous_3_months - union all - select * - from metric_aggregation_previous_1_month + {% for time_window in time_window_aggregations %} + {% set from = time_window.preceeding_from | int %} + {% set to = time_window.preceeding_to | int %} + {% set include_history = time_window.include_all_history %} + select + date, + id_deal, + client_type, + business_scope, + main_deal_name, + has_active_pms, + active_pms_list, + active_accommodations_per_deal_segmentation, + main_billing_country_iso_3_per_deal, + deal_lifecycle_state, + '{{ time_window.time_window_name }}' as time_window, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "date", + "min", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "date", + "max", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "created_bookings", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "listings_booked_in_month", + "avg", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "total_revenue_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "total_guest_payments_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_operator_net_fees_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_apis_net_fees_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_waiver_paid_back_to_host_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_host_resolution_amount_paid_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "xero_host_resolution_payment_count", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "revenue_retained_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }}, + {{ + calculate_aggregation_between_preceeding_x_and_y( + "revenue_retained_post_resolutions_in_gbp", + "sum", + "id_deal", + "date", + from, + to, + include_history, + ) + }} + from deal_history_from_previous_months + + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ) select -- Primary key