data-dwh-dbt-project/models/intermediate/cross/int_mtd_deal_metrics.sql

126 lines
4.7 KiB
MySQL
Raw Normal View History

/*
This model provides Month-To-Date (MTD) based on Deal metrics.
*/
{% set dimensions = get_kpi_dimensions() %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_mtd_deal_lifecycle as (select * from {{ ref("int_mtd_deal_lifecycle") }}),
int_dates_mtd_by_dimension as (
select * from {{ ref("int_dates_mtd_by_dimension") }}
),
int_core__mtd_accommodation_segmentation as (
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
),
int_core__deal as (select * from {{ ref("int_core__deal") }}),
deals_metric_aggregation_per_date as (
{% for dimension in dimensions %}
select
al.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(
distinct case
when al.deal_lifecycle_state = '01-New'
then al.id_deal
else null
end
) as new_deals,
count(
distinct case
when al.deal_lifecycle_state = '02-Never Booked'
then al.id_deal
else null
end
) as never_booked_deals,
count(
distinct case
when al.deal_lifecycle_state = '03-First Time Booked'
then al.id_deal
else null
end
) as first_time_booked_deals,
count(
distinct case
when al.deal_lifecycle_state = '04-Active'
then al.id_deal
else null
end
) as active_deals,
count(
distinct case
when al.deal_lifecycle_state = '05-Churning'
then al.id_deal
else null
end
) as churning_deals,
count(
distinct case
when al.deal_lifecycle_state = '06-Inactive'
then al.id_deal
else null
end
) as inactive_deals,
count(
distinct case
when al.deal_lifecycle_state = '07-Reactivated'
then al.id_deal
else null
end
) as reactivated_deals,
sum(
case when has_been_booked_within_current_month then 1 else 0 end
) as deals_booked_in_month,
sum(
case when has_been_booked_within_last_6_months then 1 else 0 end
) as deals_booked_in_6_months,
sum(
case when has_been_booked_within_last_12_months then 1 else 0 end
) as deals_booked_in_12_months
from int_mtd_deal_lifecycle al
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join
int_core__mtd_accommodation_segmentation mas
on al.id_deal = mas.id_deal
and al.date = mas.date
Merged PR 2689: KPIs by Billing Country # Description Adds Billing Country dimension in KPIs, but does not expose them to reporting yet. Silly thing, based on the macros I built, I cannot make incremental changes unless changing all models. This will need to be adapted, happy to hear your thoughts on how we do it. Additionally, I have lack of performance of the model `mtd_guest_payments_metrics`. It takes around 5 min to execute, but technically the end-to-end runs in one shoot without breaking. It's a complex PR because it changes many files, but you will see that: * It mostly changes the join conditions for the dimensions or the schema tests, * I tried to be very careful and add things step-by-step in the commits. Goal is NOT to complete the PR yet until we see how we can improve performance. I can say though that data end-to-end looks ok to me, but would benefit from checking with production data for the new dimension Update 30th Aug * Added a new commit that includes `id_user_host` in `int_core__verification_payments`. Happy to discuss if it makes sense or not. But it changes the execution from ~600 sec to ~6 sec because it avoids a massive repeated join with `verification_requests`. # 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. - [ ] I've picked the right materialization for the affected models. **To check because of performance issues** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #19082
2024-09-04 10:17:12 +00:00
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__deal ud
on al.id_deal = ud.id_deal
Merged PR 2743: Fixes deal-based issues on the billing country dimension # Description Before deploying KPIs by Billing Country, we spotted some issues that were basically increases on the volumes of any metric on the by billing country dimension that was based on Deal. This means, `int_core__mtd_deal_metrics` and `int_xero__mtd_invoicing_metrics`. This PR changes the following: * Now the 2 abovementioned models depend on the `int_core__deal` model, instead of `int_core__user_host` (thus removing duplicated stuff) * Now all models use the main billing country at deal level, instead of doing it so at host level. The reason is that some small amount of hosts that share the same deal can have a different billing country. To avoid weird stuff, everything points to this simplification - that in general, it's not a massive change in the output. * In order to do so easily, the 3 main billing country per deal fields have been propagated to `int_core__user_host` To exemplify the solution, find here a snapshot of the differences in behavior: ``` select dimension, sum(deals_booked_in_month) as deals_booked_1, sum(deals_booked_in_6_months) as deals_booked_6, sum(deals_booked_in_12_months) as deals_booked_12, sum(total_revenue_in_gbp) as total_revenue, sum(xero_operator_net_fees_in_gbp) as operator_revenue, sum(xero_booking_net_fees_in_gbp) as booking_fees, sum(xero_listing_net_fees_in_gbp) as listing_fees, sum(xero_verification_net_fees_in_gbp) as verification_fees, sum(total_guest_revenue_in_gbp) as guest_revenue, sum(xero_waiver_paid_back_to_host_in_gbp) as waiver_paid_back_to_hosts, sum(waiver_net_fees_in_gbp) as waiver_net_fees from intermediate.int_mtd_vs_previous_year_metrics where date in ('2024-01-31') group by 1 order by 1 ``` Production: ![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/2743/attachments/image.png) vs. Local: ![image (2).png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/2743/attachments/image%20%282%29.png) Keep in mind that still Global dimension can be greater than any other dimension aggregated since not all users have a deal. Mismatches between the other 2 dimensions might be linked to the dump. Commits are meaningful and help navigate in the changes. # 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: #20823
2024-09-05 09:53:16 +00:00
and ud.main_billing_country_iso_3_per_deal is not null
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.dimension,
d.dimension_value,
d.is_end_of_month,
d.is_current_month,
nullif(l.new_deals, 0) as new_deals,
nullif(l.never_booked_deals, 0) as never_booked_deals,
nullif(l.first_time_booked_deals, 0) as first_time_booked_deals,
nullif(l.active_deals, 0) as active_deals,
nullif(l.churning_deals, 0) as churning_deals,
nullif(l.inactive_deals, 0) as inactive_deals,
nullif(l.reactivated_deals, 0) as reactivated_deals,
nullif(l.deals_booked_in_month, 0) as deals_booked_in_month,
nullif(l.deals_booked_in_6_months, 0) as deals_booked_in_6_months,
nullif(l.deals_booked_in_12_months, 0) as deals_booked_in_12_months
from int_dates_mtd_by_dimension d
left join
deals_metric_aggregation_per_date l
on l.date = d.date
and l.dimension = d.dimension
and l.dimension_value = d.dimension_value