Added ratios to deal models

This commit is contained in:
Joaquin Ossa 2025-01-24 14:47:41 +01:00
parent 720185f235
commit e63a093991
4 changed files with 124 additions and 12 deletions

View file

@ -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

View file

@ -387,6 +387,16 @@ with
-1,
1
)}} as revenue_retained_ratio,
-- INCOME RETAINED POST RESOLUTIONS--
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
) as revenue_retained_post_resolutions_in_gbp,
{{
return_capped_value(
"nullif(
@ -407,16 +417,6 @@ with
)
}} as revenue_retained_post_resolutions_ratio,
-- INCOME RETAINED POST RESOLUTIONS--
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
) as revenue_retained_post_resolutions_in_gbp,
-- ONBOARDING MRR METRIC --
onboarding_mrr.expected_mrr as expected_mrr

View file

@ -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

View file

@ -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.