diff --git a/macros/calculate_aggregation_between_preceeding_x_and_y.sql b/macros/calculate_aggregation_between_preceeding_x_and_y.sql new file mode 100644 index 0000000..55153b6 --- /dev/null +++ b/macros/calculate_aggregation_between_preceeding_x_and_y.sql @@ -0,0 +1,19 @@ +/* +This macro calculates the aggregation of a metric over a partition of a column, +ordered by another column, with a window of x and y preceeding rows. + +It's designed to be placed within a SELECT statement. +*/ +{% macro calculate_aggregation_between_preceeding_x_and_y( + metric, + aggregation="sum", + partition_by="id_deal", + order_by="date", + x=12, + y=1 +) %} + {{ aggregation }} ({{ metric }}) over ( + partition by {{ partition_by }} + order by {{ order_by }} rows between {{ x }} preceding and {{ y }} preceding + ) as {{ aggregation }}_{{ metric }} +{% endmacro %} diff --git a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql index 713b1e3..eb982be 100644 --- a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql @@ -188,16 +188,16 @@ select listings.listings_booked_in_month, 0 ) as total_revenue_per_listings_booked_in_month, - -- INCOME RETAINED -- + -- REVENUE RETAINED -- nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0) + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), 0 - ) as income_retained_in_gbp, + ) as revenue_retained_in_gbp, - -- INCOME RETAINED POST RESOLUTIONS-- + -- REVENUE RETAINED POST RESOLUTIONS-- nullif( coalesce(guest_payments.total_guest_payments_in_gbp, 0) + coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0) @@ -205,7 +205,7 @@ select + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0) + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), 0 - ) as income_retained_post_resolutions_in_gbp + ) as revenue_retained_post_resolutions_in_gbp from int_kpis__agg_dates_main_kpis d left join int_kpis__dimension_deals ikdd on d.dimension_value = ikdd.id_deal 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 new file mode 100644 index 0000000..eb6629e --- /dev/null +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal_by_time_window.sql @@ -0,0 +1,328 @@ +{{ config(materialized="table", unique_key=["date", "id_deal"]) }} +with + int_monthly_aggregated_metrics_history_by_deal as ( + select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }} + ), + int_hubspot__deal as ( + select * from {{ ref("int_hubspot__deal") }} + ), + metric_aggregation_previous_12_months as ( + select + date, + id_deal, + main_deal_name, + 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 + ), + metric_aggregation_previous_3_months as ( + select + date, + id_deal, + main_deal_name, + 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 + ), + metric_aggregation_previous_1_month as ( + select + date, + id_deal, + main_deal_name, + 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 + ), + metric_aggregation_by_deal as ( + select * + from metric_aggregation_previous_12_months + union all + select * + from metric_aggregation_previous_3_months + union all + select * + from metric_aggregation_previous_1_month + ) + select + -- Primary key + mabd.date, + mabd.id_deal, + mabd.time_window, + + -- Window attributes + date_trunc('month', mabd.min_date)::date as metric_from_date, + mabd.max_date as metric_to_date, + + -- Deal attributes + mabd.main_deal_name, + mabd.main_billing_country_iso_3_per_deal, + mabd.deal_lifecycle_state, + d.deal_hubspot_stage, + d.account_manager, + d.live_date_utc, + d.cancellation_date_utc, + + -- Windowed metrics + mabd.sum_created_bookings as created_bookings, + mabd.avg_listings_booked_in_month as listings_booked_in_month, + mabd.sum_total_revenue_in_gbp as total_revenue_in_gbp, + mabd.sum_revenue_retained_in_gbp as revenue_retained_in_gbp, + mabd.sum_xero_waiver_paid_back_to_host_in_gbp as waiver_paid_back_to_host_in_gbp, + mabd.sum_revenue_retained_in_gbp + / nullif(mabd.sum_total_revenue_in_gbp,0) as revenue_retained_ratio, + coalesce(mabd.sum_xero_operator_net_fees_in_gbp,0) + + coalesce(mabd.sum_xero_apis_net_fees_in_gbp,0) as invoiced_revenue_in_gbp, + mabd.sum_total_guest_payments_in_gbp as guest_payments_in_gbp, + mabd.sum_total_guest_payments_in_gbp + + mabd.sum_xero_waiver_paid_back_to_host_in_gbp as guest_revenue_retained_in_gbp, + (mabd.sum_total_guest_payments_in_gbp + mabd.sum_xero_waiver_paid_back_to_host_in_gbp) + / nullif(mabd.sum_total_guest_payments_in_gbp,0) as guest_revenue_retained_ratio, + mabd.sum_xero_host_resolution_payment_count as host_resolution_payment_count, + mabd.sum_xero_host_resolution_amount_paid_in_gbp as host_resolution_amount_paid_in_gbp, + mabd.sum_revenue_retained_post_resolutions_in_gbp + as revenue_retained_post_resolutions_in_gbp, + mabd.sum_revenue_retained_post_resolutions_in_gbp + / nullif(mabd.sum_revenue_retained_in_gbp,0) + as revenue_retained_post_resolutions_ratio_to_retained_revenue, + mabd.sum_revenue_retained_post_resolutions_in_gbp + / nullif(mabd.sum_total_revenue_in_gbp,0) + as revenue_retained_post_resolutions_ratio_to_total_revenue + from metric_aggregation_by_deal mabd + left join int_hubspot__deal d on mabd.id_deal = d.id_deal diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index a218351..76a9d7a 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1400,3 +1400,242 @@ models: - name: created_date_utc data_type: date description: "Date of creation of the verification in the system" + + - name: int_monthly_aggregated_metrics_history_by_deal_by_time_window + description: | + This model aggregates monthly historic metrics for deals over different time windows. + It provides insights into bookings, listings, revenue, retained revenue and + additional ratios. + The data is segmented by deal and time window for detailed analysis. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - id_deal + - time_window + + columns: + - name: date + data_type: date + description: | + The last day of the month or yesterday for historic metrics. + It's the same date as for KPIs related models. + tests: + - not_null + + - name: id_deal + data_type: character varying + description: Id of the deal associated to the host. + tests: + - not_null + + - name: time_window + data_type: character varying + description: | + Identifier of the time window used for the aggregation of the metrics. + tests: + - not_null + - accepted_values: + values: + - Previous 12 months + - Previous 3 months + - Previous month + + - name: metric_from_date + data_type: date + description: | + The first day of the month corresponding to the lower bound + range in which the metric is computed. It can be null if + there's no previous history for that deal. It can vary from + deal to deal depending on the number of months the deal has + been active. + + - name: metric_to_date + data_type: date + description: | + The first day of the month corresponding to the upper bound + range in which the metric is computed. It can be null if + there's no previous history for that deal. + + - name: main_deal_name + data_type: string + description: | + Main name for this ID deal. + tests: + - not_null + + - name: main_billing_country_iso_3_per_deal + data_type: string + description: | + ISO 3166-1 alpha-3 main country code in which the Deal is billed. + In some cases it's null. + + - name: main_billing_country_name_per_deal + data_type: string + description: | + Main country name in which the Deal is billed. + In some cases it's null. + + - name: deal_hubspot_stage + data_type: string + description: | + Hubspot stage of the deal. + In some cases it's null. + + - name: account_manager + data_type: string + description: | + Account manager of the deal. + In some cases it's null. + + - name: live_date_utc + data_type: date + description: | + Date when the deal went live according to + Hubspot. In some cases it's null. + + - name: cancellation_date_utc + data_type: date + description: | + Date when the deal was cancelled according to + Hubspot. It can be null if the deal has never + churned. + + - name: created_bookings + data_type: integer + description: | + Total amount of bookings created by the deal + in the time window. It can be null if no bookings + were created. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: listings_booked_in_month + data_type: decimal + description: | + Average amount of listings booked in month by the deal + in the time window. It can be null if no listings + were booked. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: total_revenue_in_gbp + data_type: decimal + description: | + Total revenue in GBP generated by the deal in the + time window. It can be null if no revenue was generated. + It can be negative. + + - name: revenue_retained_in_gbp + data_type: decimal + description: | + Total revenue in GBP retained by the deal in the + time window, post host takeaway waivers. + It can be null if no revenue was retained. + It can be negative. + + - name: waiver_paid_back_to_host_in_gbp + data_type: decimal + description: | + Total amount of waivers paid back to the host in GBP + in the time window. It can be null if no waivers were + paid back. It's displayed as a negative value. + + - name: revenue_retained_ratio + data_type: decimal + description: | + Ratio of the revenue retained by the deal with respect + to the total revenue generated in the time window. + It can be null if no revenue was generated. In some + extreme cases, waiver paid back to host can be higher + than zero thus this ratio can be higher than 1. In some + cases the ratio can be lower than 0 if we payout more + than we retain. + + - name: invoiced_revenue_in_gbp + data_type: decimal + description: | + Total amount of revenue in GBP invoiced to the host + in the time window. It considers both Operator revenue as + well as APIs revenue. It can be null if no revenue was + invoiced to the host. It can be negative. + + - name: guest_payments_in_gbp + data_type: decimal + description: | + Total amount of payments in GBP made by the guest + in the time window. It can be null if no payments + were made by the guest. It can be negative. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: guest_revenue_retained_in_gbp + data_type: decimal + description: | + Total amount of revenue in GBP retained by the deal + from the guest in the time window, post host takeaway waivers. + It can be null if no revenue was retained from the guest. + It can be negative. + + - name: guest_revenue_retained_ratio + data_type: decimal + description: | + Ratio of the revenue retained by the deal from the guest + with respect to the total revenue generated in the time window. + It can be null if no guest revenue was generated. In some + extreme cases, this ratio can be higher than 1 if waiver paid + back to host is higher than zero. Additionally, in some cases, + the ratio can be lower than 0 if we payout more than we retain. + + - name: host_resolution_payment_count + data_type: integer + description: | + Total amount of resolution payments made to the host + in the time window. It can be null if no resolution + payments were made by the host. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: host_resolution_amount_paid_in_gbp + data_type: decimal + description: | + Total amount of resolution payments made to the host + in GBP in the time window. It can be null if no resolution + payments were made by the host. It can be negative. + It's displayed as a negative value. In some extreme + cases, it can be higher than 0. + + - name: revenue_retained_post_resolutions_in_gbp + data_type: decimal + description: | + Total amount of revenue in GBP retained by the deal + post waiver payouts and resolution payouts in the time window. + It can be null if no revenue was retained post resolution payments. + It can be negative, thus indicating that we are losing money. + + - name: revenue_retained_post_resolutions_ratio_to_retained_revenue + data_type: decimal + description: | + Ratio of the revenue retained by the deal post resolution + payments with respect to the revenue retained by the deal + in the time window. It can be null if no revenue was retained + post resolution payments. In some extreme cases, this ratio + can be lower and higher than 0 and 1, respectively. + + - name: revenue_retained_post_resolutions_ratio_to_total_revenue + data_type: decimal + description: | + Ratio of the revenue retained by the deal post resolution + payments with respect to the total revenue generated by the deal + in the time window. It can be null if no revenue was generated. + In some extreme cases, this ratio can be lower and higher than 0 and 1, + respectively.