Merged PR 2236: Refactor of already exposed metrics: listings, deals and guest journeys
Following yesterday's refactor of booking metrics, this PR provides a refactor of already exposed metrics: listings, deals and guest journeys. -> Data is consistent with values already exposed. Changes: - for `int_core__mtd_listing_metrics`, `int_core__mtd_deal_metrics` and `int_core__mtd_guest_journey_metrics`: 1. remove the computation of the previous year metric value and the relative increment (last part of the query) 2. re-apply the formatting - for `int_mtd_vs_previous_year_metrics`: 1. Reference listings, deals and GJ models 2. Include the metrics for these types in the `plain_kpi_combination` CTE 3. Add the computation of previous year and relative increment using the macro - for `int_core__mtd_aggregated_metrics` 1. Remove and "hardcode" sources since all metrics now depend exclusively of `int_mtd_vs_previous_year_metrics` This PR does not alter the exposed metrics in the production report. It does not aim to change the name of the reporting/intermediate models that expose the information, it will be done in a separated PR. Documentation: https://www.notion.so/knowyourguest-superhog/Refactoring-Business-KPIs-5deb6aadddb34884ae90339402ac16e3 Related work items: #18202
This commit is contained in:
parent
409ac47591
commit
ca8334f1da
5 changed files with 299 additions and 287 deletions
|
|
@ -3,99 +3,94 @@ This model provides Month-To-Date (MTD) based on Accommodation metrics.
|
|||
|
||||
*/
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
int_core__mtd_accommodation_lifecycle as (select * from {{ ref("int_core__mtd_accommodation_lifecycle") }}),
|
||||
with
|
||||
int_core__mtd_accommodation_lifecycle as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_lifecycle") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
listings_metric_aggregation_per_date as (
|
||||
select
|
||||
select
|
||||
al.date,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '01-New' then al.id_accommodation else null end) as new_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '02-Never Booked' then al.id_accommodation else null end) as never_booked_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '03-First Time Booked' then al.id_accommodation else null end) as first_time_booked_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '04-Active' then al.id_accommodation else null end) as active_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '05-Churning' then al.id_accommodation else null end) as churning_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '06-Inactive' then al.id_accommodation else null end) as inactive_listings,
|
||||
COUNT(distinct case when al.accommodation_lifecycle_state = '07-Reactivated' then al.id_accommodation else null end) as reactivated_listings,
|
||||
SUM(case when has_been_booked_within_current_month then 1 else 0 end) as listings_booked_in_month,
|
||||
SUM(case when has_been_booked_within_last_6_months then 1 else 0 end) as listings_booked_in_6_months,
|
||||
SUM(case when has_been_booked_within_last_12_months then 1 else 0 end) as listings_booked_in_12_months
|
||||
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '01-New'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as new_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '02-Never Booked'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as never_booked_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '03-First Time Booked'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as first_time_booked_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '04-Active'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as active_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '05-Churning'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as churning_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '06-Inactive'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as inactive_listings,
|
||||
count(
|
||||
distinct case
|
||||
when al.accommodation_lifecycle_state = '07-Reactivated'
|
||||
then al.id_accommodation
|
||||
else null
|
||||
end
|
||||
) as reactivated_listings,
|
||||
sum(
|
||||
case when has_been_booked_within_current_month then 1 else 0 end
|
||||
) as listings_booked_in_month,
|
||||
sum(
|
||||
case when has_been_booked_within_last_6_months then 1 else 0 end
|
||||
) as listings_booked_in_6_months,
|
||||
sum(
|
||||
case when has_been_booked_within_last_12_months then 1 else 0 end
|
||||
) as listings_booked_in_12_months
|
||||
|
||||
from int_core__mtd_accommodation_lifecycle al
|
||||
group by al.date
|
||||
),
|
||||
main_kpi as (
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
nullif(l.new_listings,0) as new_listings,
|
||||
nullif(l.never_booked_listings,0) as never_booked_listings,
|
||||
nullif(l.first_time_booked_listings,0) as first_time_booked_listings,
|
||||
nullif(l.active_listings,0) as active_listings,
|
||||
nullif(l.churning_listings,0) as churning_listings,
|
||||
nullif(l.inactive_listings,0) as inactive_listings,
|
||||
nullif(l.reactivated_listings,0) as reactivated_listings,
|
||||
nullif(l.listings_booked_in_month,0) as listings_booked_in_month,
|
||||
nullif(l.listings_booked_in_6_months,0) as listings_booked_in_6_months,
|
||||
nullif(l.listings_booked_in_12_months,0) as listings_booked_in_12_months
|
||||
from int_dates_mtd d
|
||||
left join listings_metric_aggregation_per_date l on l.date = d.date
|
||||
)
|
||||
-- Pivoting to get previous year for each line & computing relative increment
|
||||
-- (rel_incr) --
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
a.year,
|
||||
a.month,
|
||||
a.day,
|
||||
a.is_end_of_month,
|
||||
a.is_current_month,
|
||||
a.date,
|
||||
b.date as previous_year_date,
|
||||
a.new_listings,
|
||||
b.new_listings as previous_year_new_listings,
|
||||
cast(a.new_listings as decimal) / b.new_listings
|
||||
- 1 as relative_increment_new_listings,
|
||||
a.never_booked_listings,
|
||||
b.never_booked_listings as previous_year_never_booked_listings,
|
||||
cast(a.never_booked_listings as decimal) / b.never_booked_listings
|
||||
- 1 as relative_increment_never_booked_listings,
|
||||
a.active_listings,
|
||||
b.active_listings as previous_year_active_listings,
|
||||
cast(a.active_listings as decimal) / b.active_listings
|
||||
- 1 as relative_increment_active_listings,
|
||||
a.churning_listings,
|
||||
b.churning_listings as previous_year_churning_listings,
|
||||
cast(a.churning_listings as decimal) / b.churning_listings
|
||||
- 1 as relative_increment_churning_listings,
|
||||
a.inactive_listings,
|
||||
b.inactive_listings as previous_year_inactive_listings,
|
||||
cast(a.inactive_listings as decimal) / b.inactive_listings
|
||||
- 1 as relative_increment_inactive_listings,
|
||||
a.reactivated_listings,
|
||||
b.reactivated_listings as previous_year_reactivated_listings,
|
||||
cast(a.reactivated_listings as decimal) / b.reactivated_listings
|
||||
- 1 as relative_increment_reactivated_listings,
|
||||
a.first_time_booked_listings,
|
||||
b.first_time_booked_listings as previous_year_first_time_booked_listings,
|
||||
cast(a.first_time_booked_listings as decimal) / b.first_time_booked_listings
|
||||
- 1 as relative_increment_first_time_booked_listings,
|
||||
a.listings_booked_in_month,
|
||||
b.listings_booked_in_month as previous_year_listings_booked_in_month,
|
||||
cast(a.listings_booked_in_month as decimal) / b.listings_booked_in_month
|
||||
- 1 as relative_increment_listings_booked_in_month,
|
||||
a.listings_booked_in_6_months,
|
||||
b.listings_booked_in_6_months as previous_year_listings_booked_in_6_months,
|
||||
cast(a.listings_booked_in_6_months as decimal) / b.listings_booked_in_6_months
|
||||
- 1 as relative_increment_listings_booked_in_6_months,
|
||||
a.listings_booked_in_12_months,
|
||||
b.listings_booked_in_12_months as previous_year_listings_booked_in_12_months,
|
||||
cast(a.listings_booked_in_12_months as decimal) / b.listings_booked_in_12_months
|
||||
- 1 as relative_increment_listings_booked_in_12_months
|
||||
from main_kpi a
|
||||
left join main_kpi b on a.month = b.month and a.year = b.year + 1
|
||||
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
nullif(l.new_listings, 0) as new_listings,
|
||||
nullif(l.never_booked_listings, 0) as never_booked_listings,
|
||||
nullif(l.first_time_booked_listings, 0) as first_time_booked_listings,
|
||||
nullif(l.active_listings, 0) as active_listings,
|
||||
nullif(l.churning_listings, 0) as churning_listings,
|
||||
nullif(l.inactive_listings, 0) as inactive_listings,
|
||||
nullif(l.reactivated_listings, 0) as reactivated_listings,
|
||||
nullif(l.listings_booked_in_month, 0) as listings_booked_in_month,
|
||||
nullif(l.listings_booked_in_6_months, 0) as listings_booked_in_6_months,
|
||||
nullif(l.listings_booked_in_12_months, 0) as listings_booked_in_12_months
|
||||
from int_dates_mtd d
|
||||
left join listings_metric_aggregation_per_date l on l.date = d.date
|
||||
|
|
|
|||
|
|
@ -1,6 +1,5 @@
|
|||
{% set metrics = [
|
||||
{
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 1,
|
||||
"metric": "Created Bookings",
|
||||
"value": "created_bookings",
|
||||
|
|
@ -9,7 +8,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 2,
|
||||
"metric": "Cancelled Bookings",
|
||||
"value": "cancelled_bookings",
|
||||
|
|
@ -18,7 +16,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 3,
|
||||
"metric": "Checkout Bookings",
|
||||
"value": "check_out_bookings",
|
||||
|
|
@ -27,7 +24,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 4,
|
||||
"metric": "Guest Journey Created",
|
||||
"value": "created_guest_journeys",
|
||||
|
|
@ -36,7 +32,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 5,
|
||||
"metric": "Guest Journey Started",
|
||||
"value": "started_guest_journeys",
|
||||
|
|
@ -45,7 +40,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 6,
|
||||
"metric": "Guest Journey Completed",
|
||||
"value": "completed_guest_journeys",
|
||||
|
|
@ -54,7 +48,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 7,
|
||||
"metric": "New Deals",
|
||||
"value": "new_deals",
|
||||
|
|
@ -63,7 +56,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 8,
|
||||
"metric": "First Time Booked Deals",
|
||||
"value": "first_time_booked_deals",
|
||||
|
|
@ -72,7 +64,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 9,
|
||||
"metric": "Deals Booked in Month",
|
||||
"value": "deals_booked_in_month",
|
||||
|
|
@ -81,7 +72,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 10,
|
||||
"metric": "Deals Booked in 6 Months",
|
||||
"value": "deals_booked_in_6_months",
|
||||
|
|
@ -90,7 +80,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 11,
|
||||
"metric": "Deals Booked in 12 Months",
|
||||
"value": "deals_booked_in_12_months",
|
||||
|
|
@ -99,7 +88,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_deal_metrics",
|
||||
"order_by": 12,
|
||||
"metric": "Churning Deals",
|
||||
"value": "churning_deals",
|
||||
|
|
@ -108,7 +96,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 13,
|
||||
"metric": "New Listings",
|
||||
"value": "new_listings",
|
||||
|
|
@ -117,7 +104,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 14,
|
||||
"metric": "First Time Booked Listings",
|
||||
"value": "first_time_booked_listings",
|
||||
|
|
@ -126,7 +112,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 15,
|
||||
"metric": "Listings Booked in Month",
|
||||
"value": "listings_booked_in_month",
|
||||
|
|
@ -135,7 +120,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 16,
|
||||
"metric": "Listings Booked in 6 Months",
|
||||
"value": "listings_booked_in_6_months",
|
||||
|
|
@ -144,7 +128,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 17,
|
||||
"metric": "Listings Booked in 12 Months",
|
||||
"value": "listings_booked_in_12_months",
|
||||
|
|
@ -153,7 +136,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_accommodation_metrics",
|
||||
"order_by": 18,
|
||||
"metric": "Churning Listings",
|
||||
"value": "churning_listings",
|
||||
|
|
@ -162,7 +144,6 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 19,
|
||||
"metric": "Guest Journey Start Rate",
|
||||
"value": "start_rate_guest_journey",
|
||||
|
|
@ -171,7 +152,6 @@
|
|||
"number_format": "percentage",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 20,
|
||||
"metric": "Guest Journey Completion Rate",
|
||||
"value": "completion_rate_guest_journey",
|
||||
|
|
@ -180,7 +160,6 @@
|
|||
"number_format": "percentage",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_guest_journey_metrics",
|
||||
"order_by": 21,
|
||||
"metric": "Guest Journey Incompletion Rate",
|
||||
"value": "incompletion_rate_guest_journey",
|
||||
|
|
@ -192,15 +171,6 @@
|
|||
with
|
||||
int_mtd_vs_previous_year_metrics as (
|
||||
select * from {{ ref("int_mtd_vs_previous_year_metrics") }}
|
||||
),
|
||||
int_core__mtd_guest_journey_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
|
||||
),
|
||||
int_core__mtd_accommodation_metrics as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_metrics") }}
|
||||
),
|
||||
int_core__mtd_deal_metrics as (
|
||||
select * from {{ ref("int_core__mtd_deal_metrics") }}
|
||||
)
|
||||
{% for metric in metrics %}
|
||||
select
|
||||
|
|
@ -218,7 +188,7 @@ with
|
|||
{{ metric.value }} as value,
|
||||
{{ metric.previous_year_value }} as previous_year_value,
|
||||
{{ metric.relative_increment }} as relative_increment
|
||||
from {{ metric.source }}
|
||||
from int_mtd_vs_previous_year_metrics
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
|
|
|
|||
|
|
@ -3,99 +3,90 @@ This model provides Month-To-Date (MTD) based on Deal metrics.
|
|||
|
||||
*/
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
int_core__mtd_deal_lifecycle as (select * from {{ ref("int_core__mtd_deal_lifecycle") }}),
|
||||
with
|
||||
int_core__mtd_deal_lifecycle as (
|
||||
select * from {{ ref("int_core__mtd_deal_lifecycle") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
deals_metric_aggregation_per_date as (
|
||||
select
|
||||
select
|
||||
al.date,
|
||||
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
|
||||
|
||||
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_core__mtd_deal_lifecycle al
|
||||
group by al.date
|
||||
),
|
||||
main_kpi as (
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
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 d
|
||||
left join deals_metric_aggregation_per_date l on l.date = d.date
|
||||
)
|
||||
-- Pivoting to get previous year for each line & computing relative increment
|
||||
-- (rel_incr) --
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
a.year,
|
||||
a.month,
|
||||
a.day,
|
||||
a.is_end_of_month,
|
||||
a.is_current_month,
|
||||
a.date,
|
||||
b.date as previous_year_date,
|
||||
a.new_deals,
|
||||
b.new_deals as previous_year_new_deals,
|
||||
cast(a.new_deals as decimal) / b.new_deals
|
||||
- 1 as relative_increment_new_deals,
|
||||
a.never_booked_deals,
|
||||
b.never_booked_deals as previous_year_never_booked_deals,
|
||||
cast(a.never_booked_deals as decimal) / b.never_booked_deals
|
||||
- 1 as relative_increment_never_booked_deals,
|
||||
a.active_deals,
|
||||
b.active_deals as previous_year_active_deals,
|
||||
cast(a.active_deals as decimal) / b.active_deals
|
||||
- 1 as relative_increment_active_deals,
|
||||
a.churning_deals,
|
||||
b.churning_deals as previous_year_churning_deals,
|
||||
cast(a.churning_deals as decimal) / b.churning_deals
|
||||
- 1 as relative_increment_churning_deals,
|
||||
a.inactive_deals,
|
||||
b.inactive_deals as previous_year_inactive_deals,
|
||||
cast(a.inactive_deals as decimal) / b.inactive_deals
|
||||
- 1 as relative_increment_inactive_deals,
|
||||
a.reactivated_deals,
|
||||
b.reactivated_deals as previous_year_reactivated_deals,
|
||||
cast(a.reactivated_deals as decimal) / b.reactivated_deals
|
||||
- 1 as relative_increment_reactivated_deals,
|
||||
a.first_time_booked_deals,
|
||||
b.first_time_booked_deals as previous_year_first_time_booked_deals,
|
||||
cast(a.first_time_booked_deals as decimal) / b.first_time_booked_deals
|
||||
- 1 as relative_increment_first_time_booked_deals,
|
||||
a.deals_booked_in_month,
|
||||
b.deals_booked_in_month as previous_year_deals_booked_in_month,
|
||||
cast(a.deals_booked_in_month as decimal) / b.deals_booked_in_month
|
||||
- 1 as relative_increment_deals_booked_in_month,
|
||||
a.deals_booked_in_6_months,
|
||||
b.deals_booked_in_6_months as previous_year_deals_booked_in_6_months,
|
||||
cast(a.deals_booked_in_6_months as decimal) / b.deals_booked_in_6_months
|
||||
- 1 as relative_increment_deals_booked_in_6_months,
|
||||
a.deals_booked_in_12_months,
|
||||
b.deals_booked_in_12_months as previous_year_deals_booked_in_12_months,
|
||||
cast(a.deals_booked_in_12_months as decimal) / b.deals_booked_in_12_months
|
||||
- 1 as relative_increment_deals_booked_in_12_months
|
||||
from main_kpi a
|
||||
left join main_kpi b on a.month = b.month and a.year = b.year + 1
|
||||
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
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 d
|
||||
left join deals_metric_aggregation_per_date l on l.date = d.date
|
||||
|
|
|
|||
|
|
@ -4,20 +4,28 @@ This model provides Month-To-Date (MTD) based on Guest Journey metrics.
|
|||
*/
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
int_core__verification_requests as (select * from {{ ref("int_core__verification_requests") }}),
|
||||
int_core__verification_payments as (select * from {{ ref("int_core__verification_payments") }}),
|
||||
int_core__verification_requests as (
|
||||
select * from {{ ref("int_core__verification_requests") }}
|
||||
),
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
first_payment_per_verification_request AS (
|
||||
select vp.id_verification_request, min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
|
||||
from int_core__verification_payments vp
|
||||
where upper(vp.payment_status) = {{ var("paid_payment_state")}}
|
||||
first_payment_per_verification_request as (
|
||||
select
|
||||
vp.id_verification_request,
|
||||
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
|
||||
from int_core__verification_payments vp
|
||||
where
|
||||
upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
and vp.id_verification_request is not null
|
||||
group by 1
|
||||
group by 1
|
||||
),
|
||||
-- Created Guest Journeys MTD --
|
||||
created_year_month as (
|
||||
select d.date, count(distinct vr.id_verification_request) as created_guest_journeys
|
||||
select
|
||||
d.date, count(distinct vr.id_verification_request) as created_guest_journeys
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__verification_requests vr
|
||||
|
|
@ -28,7 +36,8 @@ with
|
|||
),
|
||||
-- Started Guest Journeys MTD --
|
||||
started_year_month as (
|
||||
select d.date, count(distinct vr.id_verification_request) as started_guest_journeys
|
||||
select
|
||||
d.date, count(distinct vr.id_verification_request) as started_guest_journeys
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__verification_requests vr
|
||||
|
|
@ -39,12 +48,15 @@ with
|
|||
),
|
||||
-- Completed Guest Journeys MTD --
|
||||
completed_year_month as (
|
||||
select d.date, count(distinct vr.id_verification_request) as completed_guest_journeys
|
||||
select
|
||||
d.date,
|
||||
count(distinct vr.id_verification_request) as completed_guest_journeys
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__verification_requests vr
|
||||
on extract(year from vr.verification_estimated_completed_date_utc) = d.year
|
||||
and extract(month from vr.verification_estimated_completed_date_utc) = d.month
|
||||
and extract(month from vr.verification_estimated_completed_date_utc)
|
||||
= d.month
|
||||
and extract(day from vr.verification_estimated_completed_date_utc) <= d.day
|
||||
group by 1
|
||||
),
|
||||
|
|
@ -58,72 +70,30 @@ with
|
|||
and extract(month from p.first_payment_paid_date_utc) = d.month
|
||||
and extract(day from p.first_payment_paid_date_utc) <= d.day
|
||||
group by 1
|
||||
),
|
||||
-- Final aggregation of subqueries + rates computation --
|
||||
main_kpi as (
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
cym.created_guest_journeys,
|
||||
sym.started_guest_journeys,
|
||||
coym.completed_guest_journeys,
|
||||
pym.paid_guest_journeys,
|
||||
cast(sym.started_guest_journeys as decimal)/cym.created_guest_journeys as start_rate_guest_journey,
|
||||
cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as completion_rate_guest_journey,
|
||||
1-cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as incompletion_rate_guest_journey,
|
||||
cast(pym.paid_guest_journeys as decimal)/coym.completed_guest_journeys as payment_rate_guest_journey
|
||||
from int_dates_mtd d
|
||||
left join created_year_month cym on d.date = cym.date
|
||||
left join started_year_month sym on d.date = sym.date
|
||||
left join completed_year_month coym on d.date = coym.date
|
||||
left join paid_year_month pym on d.date = pym.date
|
||||
)
|
||||
-- Pivoting to get previous year for each line & computing relative increment
|
||||
-- (rel_incr) --
|
||||
-- Final aggregation of subqueries + rates computation --
|
||||
select
|
||||
a.year,
|
||||
a.month,
|
||||
a.day,
|
||||
a.is_end_of_month,
|
||||
a.is_current_month,
|
||||
a.date,
|
||||
b.date as previous_year_date,
|
||||
a.created_guest_journeys,
|
||||
b.created_guest_journeys as previous_year_created_guest_journeys,
|
||||
cast(a.created_guest_journeys as decimal) / b.created_guest_journeys
|
||||
- 1 as relative_increment_created_guest_journeys,
|
||||
a.started_guest_journeys,
|
||||
b.started_guest_journeys as previous_year_started_guest_journeys,
|
||||
cast(a.started_guest_journeys as decimal) / b.started_guest_journeys
|
||||
- 1 as relative_increment_started_guest_journeys,
|
||||
a.completed_guest_journeys,
|
||||
b.completed_guest_journeys as previous_year_completed_guest_journeys,
|
||||
cast(a.completed_guest_journeys as decimal) / b.completed_guest_journeys
|
||||
- 1 as relative_increment_completed_guest_journeys,
|
||||
a.paid_guest_journeys,
|
||||
b.paid_guest_journeys as previous_year_paid_guest_journeys,
|
||||
cast(a.paid_guest_journeys as decimal) / b.paid_guest_journeys
|
||||
- 1 as relative_increment_paid_guest_journeys,
|
||||
a.start_rate_guest_journey,
|
||||
b.start_rate_guest_journey as previous_year_start_rate_guest_journey,
|
||||
cast(a.start_rate_guest_journey as decimal) / b.start_rate_guest_journey
|
||||
- 1 as relative_increment_start_rate_guest_journey,
|
||||
a.completion_rate_guest_journey,
|
||||
b.completion_rate_guest_journey as previous_year_completion_rate_guest_journey,
|
||||
cast(a.completion_rate_guest_journey as decimal) / b.completion_rate_guest_journey
|
||||
- 1 as relative_increment_completion_rate_guest_journey,
|
||||
a.incompletion_rate_guest_journey,
|
||||
b.incompletion_rate_guest_journey as previous_year_incompletion_rate_guest_journey,
|
||||
cast(a.incompletion_rate_guest_journey as decimal) / b.incompletion_rate_guest_journey
|
||||
- 1 as relative_increment_incompletion_rate_guest_journey,
|
||||
a.payment_rate_guest_journey,
|
||||
b.payment_rate_guest_journey as previous_year_payment_rate_guest_journey,
|
||||
cast(a.payment_rate_guest_journey as decimal) / b.payment_rate_guest_journey
|
||||
- 1 as relative_increment_payment_rate_guest_journey
|
||||
from main_kpi a
|
||||
left join main_kpi b on a.month = b.month and a.year = b.year + 1
|
||||
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
cym.created_guest_journeys,
|
||||
sym.started_guest_journeys,
|
||||
coym.completed_guest_journeys,
|
||||
pym.paid_guest_journeys,
|
||||
cast(sym.started_guest_journeys as decimal)
|
||||
/ cym.created_guest_journeys as start_rate_guest_journey,
|
||||
cast(coym.completed_guest_journeys as decimal)
|
||||
/ sym.started_guest_journeys as completion_rate_guest_journey,
|
||||
1
|
||||
- cast(coym.completed_guest_journeys as decimal)
|
||||
/ sym.started_guest_journeys as incompletion_rate_guest_journey,
|
||||
cast(pym.paid_guest_journeys as decimal)
|
||||
/ coym.completed_guest_journeys as payment_rate_guest_journey
|
||||
from int_dates_mtd d
|
||||
left join created_year_month cym on d.date = cym.date
|
||||
left join started_year_month sym on d.date = sym.date
|
||||
left join completed_year_month coym on d.date = coym.date
|
||||
left join paid_year_month pym on d.date = pym.date
|
||||
|
|
|
|||
|
|
@ -8,6 +8,15 @@ with
|
|||
int_core__mtd_booking_metrics as (
|
||||
select * from {{ ref("int_core__mtd_booking_metrics") }}
|
||||
),
|
||||
int_core__mtd_guest_journey_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
|
||||
),
|
||||
int_core__mtd_accommodation_metrics as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_metrics") }}
|
||||
),
|
||||
int_core__mtd_deal_metrics as (
|
||||
select * from {{ ref("int_core__mtd_deal_metrics") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
plain_kpi_combination as (
|
||||
|
|
@ -18,12 +27,55 @@ with
|
|||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
d.date,
|
||||
|
||||
-- BOOKINGS --
|
||||
bookings.created_bookings,
|
||||
bookings.check_out_bookings,
|
||||
bookings.cancelled_bookings
|
||||
bookings.cancelled_bookings,
|
||||
|
||||
-- GUEST JOURNEYS --
|
||||
guest_journeys.created_guest_journeys,
|
||||
guest_journeys.started_guest_journeys,
|
||||
guest_journeys.completed_guest_journeys,
|
||||
guest_journeys.paid_guest_journeys,
|
||||
guest_journeys.start_rate_guest_journey,
|
||||
guest_journeys.completion_rate_guest_journey,
|
||||
guest_journeys.incompletion_rate_guest_journey,
|
||||
guest_journeys.payment_rate_guest_journey,
|
||||
|
||||
-- DEALS --
|
||||
deals.new_deals,
|
||||
deals.never_booked_deals,
|
||||
deals.first_time_booked_deals,
|
||||
deals.active_deals,
|
||||
deals.churning_deals,
|
||||
deals.inactive_deals,
|
||||
deals.reactivated_deals,
|
||||
deals.deals_booked_in_month,
|
||||
deals.deals_booked_in_6_months,
|
||||
deals.deals_booked_in_12_months,
|
||||
|
||||
-- LISTINGS (ACCOMMODATIONS) --
|
||||
accommodations.new_listings,
|
||||
accommodations.never_booked_listings,
|
||||
accommodations.first_time_booked_listings,
|
||||
accommodations.active_listings,
|
||||
accommodations.churning_listings,
|
||||
accommodations.inactive_listings,
|
||||
accommodations.reactivated_listings,
|
||||
accommodations.listings_booked_in_month,
|
||||
accommodations.listings_booked_in_6_months,
|
||||
accommodations.listings_booked_in_12_months
|
||||
|
||||
from int_dates_mtd d
|
||||
left join int_core__mtd_booking_metrics bookings
|
||||
on d.date = bookings.date
|
||||
left join int_core__mtd_guest_journey_metrics guest_journeys
|
||||
on d.date = guest_journeys.date
|
||||
left join int_core__mtd_accommodation_metrics accommodations
|
||||
on d.date = accommodations.date
|
||||
left join int_core__mtd_deal_metrics deals
|
||||
on d.date = deals.date
|
||||
)
|
||||
select
|
||||
current.year,
|
||||
|
|
@ -37,7 +89,41 @@ select
|
|||
-- BOOKINGS --
|
||||
{{ calculate_safe_relative_increment('created_bookings') }},
|
||||
{{ calculate_safe_relative_increment('check_out_bookings') }},
|
||||
{{ calculate_safe_relative_increment('cancelled_bookings') }}
|
||||
{{ calculate_safe_relative_increment('cancelled_bookings') }},
|
||||
|
||||
-- GUEST JOURNEYS --
|
||||
{{ calculate_safe_relative_increment('created_guest_journeys') }},
|
||||
{{ calculate_safe_relative_increment('started_guest_journeys') }},
|
||||
{{ calculate_safe_relative_increment('completed_guest_journeys') }},
|
||||
{{ calculate_safe_relative_increment('paid_guest_journeys') }},
|
||||
{{ calculate_safe_relative_increment('start_rate_guest_journey') }},
|
||||
{{ calculate_safe_relative_increment('completion_rate_guest_journey') }},
|
||||
{{ calculate_safe_relative_increment('incompletion_rate_guest_journey') }},
|
||||
{{ calculate_safe_relative_increment('payment_rate_guest_journey') }},
|
||||
|
||||
-- DEALS --
|
||||
{{ calculate_safe_relative_increment('new_deals') }},
|
||||
{{ calculate_safe_relative_increment('never_booked_deals') }},
|
||||
{{ calculate_safe_relative_increment('first_time_booked_deals') }},
|
||||
{{ calculate_safe_relative_increment('active_deals') }},
|
||||
{{ calculate_safe_relative_increment('churning_deals') }},
|
||||
{{ calculate_safe_relative_increment('inactive_deals') }},
|
||||
{{ calculate_safe_relative_increment('reactivated_deals') }},
|
||||
{{ calculate_safe_relative_increment('deals_booked_in_month') }},
|
||||
{{ calculate_safe_relative_increment('deals_booked_in_6_months') }},
|
||||
{{ calculate_safe_relative_increment('deals_booked_in_12_months') }},
|
||||
|
||||
-- LISTINGS --
|
||||
{{ calculate_safe_relative_increment('new_listings') }},
|
||||
{{ calculate_safe_relative_increment('never_booked_listings') }},
|
||||
{{ calculate_safe_relative_increment('first_time_booked_listings') }},
|
||||
{{ calculate_safe_relative_increment('active_listings') }},
|
||||
{{ calculate_safe_relative_increment('churning_listings') }},
|
||||
{{ calculate_safe_relative_increment('inactive_listings') }},
|
||||
{{ calculate_safe_relative_increment('reactivated_listings') }},
|
||||
{{ calculate_safe_relative_increment('listings_booked_in_month') }},
|
||||
{{ calculate_safe_relative_increment('listings_booked_in_6_months') }},
|
||||
{{ calculate_safe_relative_increment('listings_booked_in_12_months') }}
|
||||
|
||||
from plain_kpi_combination current
|
||||
left join plain_kpi_combination previous_year
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue