Merged PR 2105: Adding listing lifecycle metrics into business KPIs

This PR will compute the listing metrics in an aggregated manner to be displayed in the Main KPIs dashboard, specifically:
- New Listings
- First Time Booked Listings
- Churning Listings
- It also adapts the computation for the already existing metrics of Listings Booked in X months

At code level, it contains the following:
- Adds `int_core__mtd_accommodation_metrics`, which computes the aggregation of the lifecycle of listings at date level (unique), being date the corresponding date from `int_dates_mtd`
- Changes `int_core__mtd_aggregated_metrics` to take the accommodation metrics from the new model. Those 3 already existing (Listings booked in X month) now read from the new model as well.
- Changes `int_core__mtd_booking_metrics` to remove unused computation, making it lighter. Specifically, it removes 1) listing related metrics, since now we have a dedicated model and 2) number of guests booked, since it's not used at all.

The resulting values in local are consistent with what is already reported in the staging report.

Related work items: #17312
This commit is contained in:
Oriol Roqué Paniagua 2024-06-25 08:14:23 +00:00
parent f23e210129
commit 0655ac8997
4 changed files with 157 additions and 91 deletions

View file

@ -0,0 +1,101 @@
/*
This model provides Month-To-Date (MTD) based on Booking metrics.
*/
{{ config(materialized="table", unique_key="date") }}
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
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
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) --
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))

View file

@ -81,7 +81,25 @@
"number_format": "integer",
},
{
"source": "int_core__mtd_booking_metrics",
"source": "int_core__mtd_accommodation_metrics",
"order_by": 13,
"metric": "New Listings",
"value": "new_listings",
"previous_year_value": "previous_year_new_listings",
"relative_increment": "relative_increment_new_listings",
"number_format": "integer",
},
{
"source": "int_core__mtd_accommodation_metrics",
"order_by": 14,
"metric": "First Time Booked Listings",
"value": "first_time_booked_listings",
"previous_year_value": "previous_year_first_time_booked_listings",
"relative_increment": "relative_increment_first_time_booked_listings",
"number_format": "integer",
},
{
"source": "int_core__mtd_accommodation_metrics",
"order_by": 15,
"metric": "Listings Booked in Month",
"value": "listings_booked_in_month",
@ -90,7 +108,7 @@
"number_format": "integer",
},
{
"source": "int_core__mtd_booking_metrics",
"source": "int_core__mtd_accommodation_metrics",
"order_by": 16,
"metric": "Listings Booked in 6 Months",
"value": "listings_booked_in_6_months",
@ -99,7 +117,7 @@
"number_format": "integer",
},
{
"source": "int_core__mtd_booking_metrics",
"source": "int_core__mtd_accommodation_metrics",
"order_by": 17,
"metric": "Listings Booked in 12 Months",
"value": "listings_booked_in_12_months",
@ -107,6 +125,15 @@
"relative_increment": "relative_increment_listings_booked_in_12_months",
"number_format": "integer",
},
{
"source": "int_core__mtd_accommodation_metrics",
"order_by": 18,
"metric": "Churning Listings",
"value": "churning_listings",
"previous_year_value": "previous_year_churning_listings",
"relative_increment": "relative_increment_churning_listings",
"number_format": "integer",
},
{
"source": "int_core__mtd_guest_journey_metrics",
"order_by": 19,
@ -141,6 +168,9 @@ with
),
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") }}
)
{% for metric in metrics %}
select

View file

@ -46,9 +46,7 @@ with
creation_month_diff as (
select
d.date,
b.id_accommodation,
b.id_user_host,
b.id_user_guest,
max(b.created_date_utc) as last_created_date,
(d.year - extract(year from max(b.created_date_utc))) * 12
+ (d.month - extract(month from max(b.created_date_utc))) as month_diff
@ -56,33 +54,12 @@ with
inner join
int_core__bookings b
on b.created_date_utc between d.date - interval '13 months' and d.date -- reduce the computation at 12 + 1 month to reduce the rows to retrieve
group by 1, 2, 3, 4, d.year, d.month
group by 1, 2, d.year, d.month
),
-- Computation of booking-based activity metrics --
booking_based_activity as (
select
cmd.date,
-- Listings activity --
count(
distinct case
when cmd.month_diff = 0 then cmd.id_accommodation else null
end
) as listings_booked_in_month,
count(
distinct case
when cmd.month_diff >= 0 and cmd.month_diff < 6
then cmd.id_accommodation
else null
end
) as listings_booked_in_6_months,
count(
distinct case
when cmd.month_diff >= 0 and cmd.month_diff < 12
then cmd.id_accommodation
else null
end
) as listings_booked_in_12_months,
count(distinct cmd.id_accommodation) as historic_booked_listings,
-- Hosts/PM activity --
count(
distinct case
@ -103,28 +80,7 @@ with
else null
end
) as hosts_booked_in_12_months,
count(distinct cmd.id_user_host) as historic_booked_hosts,
-- Guests activity --
count(
distinct case
when cmd.month_diff = 0 then cmd.id_user_guest else null
end
) as guests_booked_in_month,
count(
distinct case
when cmd.month_diff >= 0 and cmd.month_diff < 6
then cmd.id_user_guest
else null
end
) as guests_booked_in_6_months,
count(
distinct case
when cmd.month_diff >= 0 and cmd.month_diff < 12
then cmd.id_user_guest
else null
end
) as guests_booked_in_12_months,
count(distinct cmd.id_user_guest) as historic_booked_guests
count(distinct cmd.id_user_host) as historic_booked_hosts
from creation_month_diff cmd
group by 1
@ -141,18 +97,10 @@ with
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_bookings,
bba.listings_booked_in_month,
bba.listings_booked_in_6_months,
bba.listings_booked_in_12_months,
bba.historic_booked_listings,
bba.hosts_booked_in_month,
bba.hosts_booked_in_6_months,
bba.hosts_booked_in_12_months,
bba.historic_booked_hosts,
bba.guests_booked_in_month,
bba.guests_booked_in_6_months,
bba.guests_booked_in_12_months,
bba.historic_booked_guests
bba.historic_booked_hosts
from int_dates_mtd d
left join created_year_month crym on crym.date = d.date
left join check_out_year_month coym on coym.date = d.date
@ -181,22 +129,6 @@ select
b.cancelled_bookings as previous_year_cancelled_bookings,
cast(a.cancelled_bookings as decimal) / b.cancelled_bookings
- 1 as relative_increment_cancelled_bookings,
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,
a.historic_booked_listings,
b.historic_booked_listings as previous_year_historic_booked_listings,
cast(a.historic_booked_listings as decimal) / b.historic_booked_listings
- 1 as relative_increment_historic_booked_listings,
a.hosts_booked_in_month,
b.hosts_booked_in_month as previous_year_hosts_booked_in_month,
cast(a.hosts_booked_in_month as decimal) / b.hosts_booked_in_month
@ -212,23 +144,7 @@ select
a.historic_booked_hosts,
b.historic_booked_hosts as previous_year_historic_booked_hosts,
cast(a.historic_booked_hosts as decimal) / b.historic_booked_hosts
- 1 as relative_increment_historic_booked_hosts,
a.guests_booked_in_month,
b.guests_booked_in_month as previous_year_guests_booked_in_month,
cast(a.guests_booked_in_month as decimal) / b.guests_booked_in_month
- 1 as relative_increment_guests_booked_in_month,
a.guests_booked_in_6_months,
b.guests_booked_in_6_months as previous_year_guests_booked_in_6_months,
cast(a.guests_booked_in_6_months as decimal) / b.guests_booked_in_6_months
- 1 as relative_increment_guests_booked_in_6_months,
a.guests_booked_in_12_months,
b.guests_booked_in_12_months as previous_year_guests_booked_in_12_months,
cast(a.guests_booked_in_12_months as decimal) / b.guests_booked_in_12_months
- 1 as relative_increment_guests_booked_in_12_months,
a.historic_booked_guests,
b.historic_booked_guests as previous_year_historic_booked_guests,
cast(a.historic_booked_guests as decimal) / b.historic_booked_guests
- 1 as relative_increment_historic_booked_guests
- 1 as relative_increment_historic_booked_hosts
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))

View file

@ -144,6 +144,11 @@ models:
- unique
- name: int_core__mtd_booking_metrics
description: |
This model contains the historic information regarding the bookings in an aggregated manner.
It's used for the business KPIs. Data is aggregated at the last day of the month and in the
days necessary for the Month-to-Date computation of the current month.
columns:
- name: date
data_type: date
@ -152,6 +157,20 @@ models:
- not_null
- unique
- name: int_core__mtd_accommodation_metrics
description: |
This model contains the historic information regarding the accommodations in an aggregated manner.
It's used for the business KPIs. Data is aggregated at the last day of the month and in the
days necessary for the Month-to-Date computation of the current month.
columns:
- name: date
data_type: date
description: The date for the month-to-date accommodation-related metrics.
tests:
- not_null
- unique
- name: int_core__mtd_aggregated_metrics
description: |
The `int_core__mtd_aggregated_metrics` model aggregates multiple metrics on a year, month, and day basis.