# Description Changes: * Creates lifecycle_daily_deal, metric_daily_deals and agg_daily_deals. These follow a different strategy due to the nature of the metrics * Modifies the dimension macro to ensure deal dimension is included in all models except these ones * Fixes production issue on currently deployed deal lifecycle and metrics # 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: #23566
120 lines
4.5 KiB
SQL
120 lines
4.5 KiB
SQL
{% set min_date = "2022-01-01" %}
|
|
{% set dimensions = ("global", "by_billing_country") %}
|
|
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
|
|
-- segmentation
|
|
with
|
|
new_deals as (
|
|
select
|
|
date,
|
|
dimension,
|
|
dimension_value,
|
|
new_deals,
|
|
never_booked_deals,
|
|
first_time_booked_deals,
|
|
active_deals,
|
|
churning_deals,
|
|
inactive_deals,
|
|
reactivated_deals,
|
|
deals_booked_in_month,
|
|
deals_booked_in_6_months,
|
|
deals_booked_in_12_months
|
|
from {{ ref("int_kpis__agg_daily_deals") }}
|
|
where
|
|
date >= '{{ min_date }}'
|
|
and dimension in {{ dimensions }}
|
|
and dimension_value <> 'UNSET'
|
|
and (is_end_of_month = true or is_month_to_date = true)
|
|
),
|
|
old_deals as (
|
|
select
|
|
date,
|
|
dimension,
|
|
dimension_value,
|
|
new_deals,
|
|
never_booked_deals,
|
|
first_time_booked_deals,
|
|
active_deals,
|
|
churning_deals,
|
|
inactive_deals,
|
|
reactivated_deals,
|
|
deals_booked_in_month,
|
|
deals_booked_in_6_months,
|
|
deals_booked_in_12_months
|
|
from {{ ref("int_mtd_deal_metrics") }}
|
|
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
|
|
),
|
|
comparison as (
|
|
select
|
|
coalesce(o.date, n.date) as date,
|
|
coalesce(o.dimension, n.dimension) as dimension,
|
|
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
|
|
o.new_deals as old_new_deals,
|
|
n.new_deals as new_new_deals,
|
|
coalesce(o.new_deals, 0) - coalesce(n.new_deals, 0) as diff_new_deals,
|
|
|
|
o.never_booked_deals as old_never_booked_deals,
|
|
n.never_booked_deals as new_never_booked_deals,
|
|
coalesce(o.never_booked_deals, 0)
|
|
- coalesce(n.never_booked_deals, 0) as diff_never_booked_deals,
|
|
|
|
o.first_time_booked_deals as old_first_time_booked_deals,
|
|
n.first_time_booked_deals as new_first_time_booked_deals,
|
|
coalesce(o.first_time_booked_deals, 0)
|
|
- coalesce(n.first_time_booked_deals, 0) as diff_first_time_booked_deals,
|
|
|
|
o.active_deals as old_active_deals,
|
|
n.active_deals as new_active_deals,
|
|
coalesce(o.active_deals, 0)
|
|
- coalesce(n.active_deals, 0) as diff_active_deals,
|
|
|
|
o.inactive_deals as old_inactive_deals,
|
|
n.inactive_deals as new_inactive_deals,
|
|
coalesce(o.inactive_deals, 0)
|
|
- coalesce(n.inactive_deals, 0) as diff_inactive_deals,
|
|
|
|
o.churning_deals as old_churning_deals,
|
|
n.churning_deals as new_churning_deals,
|
|
coalesce(o.churning_deals, 0)
|
|
- coalesce(n.churning_deals, 0) as diff_churning_deals,
|
|
|
|
o.reactivated_deals as old_reactivated_deals,
|
|
n.reactivated_deals as new_reactivated_deals,
|
|
coalesce(o.reactivated_deals, 0)
|
|
- coalesce(n.reactivated_deals, 0) as diff_reactivated_deals,
|
|
|
|
o.deals_booked_in_month as old_deals_booked_in_month,
|
|
n.deals_booked_in_month as new_deals_booked_in_month,
|
|
coalesce(o.deals_booked_in_month, 0)
|
|
- coalesce(n.deals_booked_in_month, 0) as diff_deals_booked_in_month,
|
|
|
|
o.deals_booked_in_6_months as old_deals_booked_in_6_months,
|
|
n.deals_booked_in_6_months as new_deals_booked_in_6_months,
|
|
coalesce(o.deals_booked_in_6_months, 0)
|
|
- coalesce(n.deals_booked_in_6_months, 0) as diff_deals_booked_in_6_months,
|
|
|
|
o.deals_booked_in_12_months as old_deals_booked_in_12_months,
|
|
n.deals_booked_in_12_months as new_deals_booked_in_12_months,
|
|
coalesce(o.deals_booked_in_12_months, 0)
|
|
- coalesce(n.deals_booked_in_12_months, 0) as diff_deals_booked_in_12_months
|
|
|
|
from old_deals o
|
|
full outer join
|
|
new_deals n
|
|
on o.date = n.date
|
|
and o.dimension = n.dimension
|
|
and o.dimension_value = n.dimension_value
|
|
)
|
|
select *
|
|
from comparison
|
|
where
|
|
diff_new_deals <> 0
|
|
or diff_never_booked_deals <> 0
|
|
or diff_first_time_booked_deals <> 0
|
|
or diff_active_deals <> 0
|
|
or diff_inactive_deals <> 0
|
|
or diff_churning_deals <> 0
|
|
or diff_reactivated_deals <> 0
|
|
or diff_deals_booked_in_month <> 0
|
|
or diff_deals_booked_in_6_months <> 0
|
|
or diff_deals_booked_in_12_months <> 0
|
|
order by date desc
|