Merged PR 3939: Fixes DWH models for new PBI on AM
# Description Mostly 2 changes: * Fix metrics with coalesces so values are displayed * Removes ratios, no longer needed. These are computed in PBI directly, to be able to compute the total figure correctly # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #25829
This commit is contained in:
parent
6d261e281e
commit
f2abd16a44
4 changed files with 108 additions and 110 deletions
|
|
@ -94,6 +94,94 @@ with
|
|||
|
||||
from int_monthly_aggregated_metrics_history_by_deal
|
||||
),
|
||||
metric_aggregation_previous_6_months as (
|
||||
select
|
||||
date,
|
||||
id_deal,
|
||||
main_deal_name,
|
||||
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
|
||||
),
|
||||
metric_aggregation_previous_3_months as (
|
||||
select
|
||||
date,
|
||||
|
|
@ -275,6 +363,9 @@ with
|
|||
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 *
|
||||
|
|
@ -300,29 +391,19 @@ with
|
|||
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_created_bookings,0) as created_bookings,
|
||||
coalesce(mabd.avg_listings_booked_in_month,0) as listings_booked_in_month,
|
||||
coalesce(mabd.sum_total_revenue_in_gbp,0) as total_revenue_in_gbp,
|
||||
coalesce(mabd.sum_revenue_retained_in_gbp,0) as revenue_retained_in_gbp,
|
||||
coalesce(mabd.sum_xero_waiver_paid_back_to_host_in_gbp,0) as waiver_paid_back_to_host_in_gbp,
|
||||
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
|
||||
coalesce(mabd.sum_total_guest_payments_in_gbp,0) as guest_payments_in_gbp,
|
||||
coalesce(mabd.sum_total_guest_payments_in_gbp,0)
|
||||
+ coalesce(mabd.sum_xero_waiver_paid_back_to_host_in_gbp,0) as guest_revenue_retained_in_gbp,
|
||||
coalesce(mabd.sum_xero_host_resolution_payment_count,0) as host_resolution_payment_count,
|
||||
coalesce(mabd.sum_xero_host_resolution_amount_paid_in_gbp,0) as host_resolution_amount_paid_in_gbp,
|
||||
coalesce(mabd.sum_revenue_retained_post_resolutions_in_gbp,0)
|
||||
as revenue_retained_post_resolutions_in_gbp
|
||||
from metric_aggregation_by_deal mabd
|
||||
left join int_hubspot__deal d on mabd.id_deal = d.id_deal
|
||||
|
|
|
|||
|
|
@ -1405,7 +1405,7 @@ models:
|
|||
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.
|
||||
additional metrics.
|
||||
The data is segmented by deal and time window for detailed analysis.
|
||||
|
||||
tests:
|
||||
|
|
@ -1439,6 +1439,7 @@ models:
|
|||
- accepted_values:
|
||||
values:
|
||||
- Previous 12 months
|
||||
- Previous 6 months
|
||||
- Previous 3 months
|
||||
- Previous month
|
||||
|
||||
|
|
@ -1545,17 +1546,6 @@ models:
|
|||
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: |
|
||||
|
|
@ -1583,16 +1573,6 @@ models:
|
|||
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: |
|
||||
|
|
@ -1621,24 +1601,6 @@ models:
|
|||
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.
|
||||
|
||||
- name: int_deals_consolidation
|
||||
description: |
|
||||
"This table contains all deal ids from different sources used in Superhog.
|
||||
|
|
|
|||
|
|
@ -22,17 +22,10 @@ select
|
|||
total_revenue_in_gbp as total_revenue_in_gbp,
|
||||
revenue_retained_in_gbp as revenue_retained_in_gbp,
|
||||
waiver_paid_back_to_host_in_gbp as waiver_paid_back_to_host_in_gbp,
|
||||
revenue_retained_ratio as revenue_retained_ratio,
|
||||
invoiced_revenue_in_gbp as invoiced_revenue_in_gbp,
|
||||
guest_payments_in_gbp as guest_payments_in_gbp,
|
||||
guest_revenue_retained_in_gbp as guest_revenue_retained_in_gbp,
|
||||
guest_revenue_retained_ratio as guest_revenue_retained_ratio,
|
||||
host_resolution_payment_count as host_resolution_payment_count,
|
||||
host_resolution_amount_paid_in_gbp as host_resolution_amount_paid_in_gbp,
|
||||
revenue_retained_post_resolutions_in_gbp
|
||||
as revenue_retained_post_resolutions_in_gbp,
|
||||
revenue_retained_post_resolutions_ratio_to_retained_revenue
|
||||
as revenue_retained_post_resolutions_ratio_to_retained_revenue,
|
||||
revenue_retained_post_resolutions_ratio_to_total_revenue
|
||||
as revenue_retained_post_resolutions_ratio_to_total_revenue
|
||||
revenue_retained_post_resolutions_in_gbp as revenue_retained_post_resolutions_in_gbp
|
||||
from int_monthly_aggregated_metrics_history_by_deal_by_time_window
|
||||
|
|
|
|||
|
|
@ -1373,7 +1373,7 @@ models:
|
|||
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.
|
||||
additional metrics.
|
||||
The data is segmented by deal and time window for detailed analysis.
|
||||
|
||||
tests:
|
||||
|
|
@ -1407,6 +1407,7 @@ models:
|
|||
- accepted_values:
|
||||
values:
|
||||
- Previous 12 months
|
||||
- Previous 6 months
|
||||
- Previous 3 months
|
||||
- Previous month
|
||||
|
||||
|
|
@ -1513,17 +1514,6 @@ models:
|
|||
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: |
|
||||
|
|
@ -1551,16 +1541,6 @@ models:
|
|||
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: |
|
||||
|
|
@ -1588,21 +1568,3 @@ models:
|
|||
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.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue