diff --git a/macros/calculate_safe_relative_increment.sql b/macros/calculate_safe_relative_increment.sql index 5e9018f..59ba448 100644 --- a/macros/calculate_safe_relative_increment.sql +++ b/macros/calculate_safe_relative_increment.sql @@ -7,8 +7,11 @@ It's designed to be placed within a SELECT statement. It ensure safe divide by zero division by applying a nullif function. */ -{% macro calculate_safe_relative_increment(metric, current='current', previous='previous_year') %} +{% macro calculate_safe_relative_increment( + metric, current="current", previous="previous_year" +) %} {{ current }}.{{ metric }}, {{ previous }}.{{ metric }} as {{ previous }}_{{ metric }}, - cast({{ current }}.{{ metric }} as decimal) / nullif({{ previous }}.{{ metric }},0) - 1 as relative_increment_{{ metric }} -{% endmacro %} \ No newline at end of file + cast({{ current }}.{{ metric }} as decimal) / nullif({{ previous }}.{{ metric }}, 0) + - 1 as relative_increment_{{ metric }} +{% endmacro %} diff --git a/macros/return_capped_value.sql b/macros/return_capped_value.sql new file mode 100644 index 0000000..b6d2889 --- /dev/null +++ b/macros/return_capped_value.sql @@ -0,0 +1,20 @@ +/* +This macro caps a given value between a specified bottom and top limit, +returning `NULL` if the input value is `NULL`. + +It uses the `LEAST` and `GREATEST` SQL functions to enforce the caps while +preserving the `NULL` values in the input. + +Parameters: +- `value`: The value to be capped. +- `cap_bottom`: The minimum limit for the value. +- `cap_top`: The maximum limit for the value. + +*/ +{% macro return_capped_value(value, cap_bottom, cap_top) %} + CASE + WHEN {{ value }} IS NULL THEN NULL + ELSE LEAST({{ cap_top }}, GREATEST({{ cap_bottom }}, {{ value }})) + END +{% 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 3c89adf..44a40fc 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 @@ -149,6 +149,18 @@ select -- HOST RESOLUTIONS -- host_resolutions.xero_host_resolution_amount_paid_in_gbp, host_resolutions.xero_host_resolution_payment_count, + cast(host_resolutions.xero_host_resolution_amount_paid_in_gbp as decimal) + / created_bookings.created_bookings + as host_resolution_amount_paid_per_created_booking, + {{ + return_capped_value( + "cast(host_resolutions.xero_host_resolution_payment_count as decimal) + / created_bookings.created_bookings", + -1, + 1 + ) + }} + as host_resolution_payment_per_created_booking_ratio, -- GUEST REVENUE AND PAYMENTS -- guest_payments.deposit_fees_in_gbp, @@ -208,6 +220,23 @@ select + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), 0 ) as revenue_retained_in_gbp, + {{ + return_capped_value( + "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 + ) / 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), + 0 + )", + -1, + 1 + )}} as revenue_retained_ratio, -- REVENUE RETAINED POST RESOLUTIONS-- nullif( @@ -217,7 +246,26 @@ 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 revenue_retained_post_resolutions_in_gbp + ) as revenue_retained_post_resolutions_in_gbp, + {{ + return_capped_value( + "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) + + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), + 0 + ) / 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), + 0 + )", + -1, + 1 + ) + }} as revenue_retained_post_resolutions_ratio 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_mtd_vs_previous_year_metrics.sql b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql index bc45c22..2e74aba 100644 --- a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql +++ b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql @@ -289,8 +289,14 @@ with cast(host_resolutions.xero_host_resolution_amount_paid_in_gbp as decimal) / created_bookings.created_bookings as host_resolution_amount_paid_per_created_booking, - cast(host_resolutions.xero_host_resolution_payment_count as decimal) - / created_bookings.created_bookings + {{ + return_capped_value( + "cast(host_resolutions.xero_host_resolution_payment_count as decimal) + / created_bookings.created_bookings", + -1, + 1 + ) + }} as host_resolution_payment_per_created_booking_ratio, -- GUEST REVENUE AND PAYMENTS -- @@ -364,31 +370,23 @@ with + coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0), 0 ) as revenue_retained_in_gbp, - 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 - ) / 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), - 0 - ) as revenue_retained_ratio, - 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) - + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), - 0 - ) / 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), - 0 - ) as revenue_retained_post_resolutions_ratio, + {{ + return_capped_value( + "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 + ) / 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), + 0 + )", + -1, + 1 + )}} as revenue_retained_ratio, -- INCOME RETAINED POST RESOLUTIONS-- nullif( @@ -399,6 +397,25 @@ with + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), 0 ) as revenue_retained_post_resolutions_in_gbp, + {{ + return_capped_value( + "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) + + coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0), + 0 + ) / 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), + 0 + )", + -1, + 1 + ) + }} as revenue_retained_post_resolutions_ratio, -- ONBOARDING MRR METRIC -- onboarding_mrr.expected_mrr as expected_mrr diff --git a/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql b/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql index 2a4c500..9a489f0 100644 --- a/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql +++ b/models/reporting/general/monthly_aggregated_metrics_history_by_deal.sql @@ -75,6 +75,16 @@ select then xero_host_resolution_payment_count else null end as xero_host_resolution_payment_count, + case + when {{ is_date_before_previous_month("date") }} + then host_resolution_amount_paid_per_created_booking + else null + end as host_resolution_amount_paid_per_created_booking, + case + when {{ is_date_before_previous_month("date") }} + then host_resolution_payment_per_created_booking_ratio + else null + end as host_resolution_payment_per_created_booking_ratio, case when {{ is_date_before_previous_month("date") }} then xero_booking_net_fees_in_gbp @@ -153,9 +163,19 @@ select then revenue_retained_in_gbp else null end as revenue_retained_in_gbp, + case + when {{ is_date_before_previous_month("date") }} + then revenue_retained_ratio + else null + end as revenue_retained_ratio, case when {{ is_date_before_previous_month("date") }} then revenue_retained_post_resolutions_in_gbp else null - end as revenue_retained_post_resolutions_in_gbp + end as revenue_retained_post_resolutions_in_gbp, + case + when {{ is_date_before_previous_month("date") }} + then revenue_retained_post_resolutions_ratio + else null + end as revenue_retained_post_resolutions_ratio from int_monthly_aggregated_metrics_history_by_deal diff --git a/models/reporting/general/schema.yml b/models/reporting/general/schema.yml index 1194b8c..8ed0a37 100644 --- a/models/reporting/general/schema.yml +++ b/models/reporting/general/schema.yml @@ -525,6 +525,50 @@ models: data_tests: - not_null + - name: host_resolution_amount_paid_per_created_booking + data_type: decimal + description: | + Host resolution amount paid divided by the number of + created bookings in the time window. It can be null if + no resolution payments were made by the host. + It can be negative or positive. + + - name: host_resolution_payment_per_created_booking_ratio + data_type: decimal + description: | + Ratio of Host resolution payment count divided by the + number of created bookings in the time window. It can be null + if no resolution payments were made by the host. + It is capped between -1 and 1. + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + max_value: 1 + strictly: false + + - name: revenue_retained_ratio + data_type: decimal + description: | + Ratio of Revenue Retained divided by Total Revenue. + It is capped between -1 and 1. It can be Null + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + max_value: 1 + strictly: false + + - name: revenue_retained_post_resolutions_ratio + data_type: decimal + description: | + Ratio of Revenue Retained Post-Resolutions + divided by Total Revenue. + It is capped between -1 and 1. It can be Null + data_tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + max_value: 1 + strictly: false + - name: monthly_growth_score_by_deal description: | The main goal of this model is to provide a growth score by deal and month.