Merged PR 2519: mtd bookings with 2 dimensions
# Description This is a first idea of how I'd like to add dimensionality in the KPIs for the mtd models. For the moment, I keep deal_id apart, so I just touch the "mtd" models, that so far only contained "global" metrics. In this case I include the listing segmentation (0, 1-5, 6-20, etc) in the bookings. To do this, I created 2 new fields: dimension and dimension_values. I also created a "master" table with `date` - `dimension` - `dimension_value` called `int_dates_mtd_by_dimension` Important notes: - I force a hardcode in `int_mtd_vs_previous_year_metrics`. This is to not break production. - You will notice how repetitive the code is starting to look. My intention with this PR is that we are happy with this approach on the naming, the strategy for joins, etc. If that's ok, next step is going to be doing macros on top. Think of the state of `int_core__mtd_booking_metrics` as the "compiled version" of the macro that should come afterwards. # 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. - [ ] 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: #19325
This commit is contained in:
parent
7177b41e19
commit
afc20f0e20
5 changed files with 289 additions and 18 deletions
|
|
@ -2,68 +2,191 @@
|
|||
This model provides Month-To-Date (MTD) based on Booking metrics.
|
||||
|
||||
*/
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
|
||||
int_core__booking_charge_events as (select * from {{ ref("int_core__booking_charge_events")}}),
|
||||
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
||||
int_core__mtd_accommodation_segmentation as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
|
||||
),
|
||||
int_core__booking_charge_events as (
|
||||
select * from {{ ref("int_core__booking_charge_events") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
int_dates_mtd_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
|
||||
|
||||
-- Created Bookings MTD --
|
||||
created_year_month as (
|
||||
select d.date, count(distinct b.id_booking) as created_bookings
|
||||
select
|
||||
d.date,
|
||||
'global' as dimension,
|
||||
'global' as dimension_value,
|
||||
count(distinct b.id_booking) as created_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.created_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.created_date_utc) <= d.day
|
||||
group by 1
|
||||
group by 1, 2, 3
|
||||
|
||||
union all
|
||||
|
||||
select
|
||||
d.date,
|
||||
'by_number_of_listings' as dimension,
|
||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
||||
count(distinct b.id_booking) as created_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.created_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.created_date_utc) <= d.day
|
||||
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
group by 1, 2, 3
|
||||
),
|
||||
-- Checkout Bookings MTD --
|
||||
check_out_year_month as (
|
||||
select d.date, count(distinct b.id_booking) as check_out_bookings
|
||||
select
|
||||
d.date,
|
||||
'global' as dimension,
|
||||
'global' as dimension_value,
|
||||
count(distinct b.id_booking) as check_out_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.check_out_date_utc) <= d.day
|
||||
group by 1
|
||||
group by 1, 2, 3
|
||||
|
||||
union all
|
||||
|
||||
select
|
||||
d.date,
|
||||
'by_number_of_listings' as dimension,
|
||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
||||
count(distinct b.id_booking) as check_out_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.check_out_date_utc) <= d.day
|
||||
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
group by 1, 2, 3
|
||||
|
||||
),
|
||||
-- Cancelled Bookings MTD --
|
||||
-- Cancellation date equivalent to the last time the cancelled booking was updated
|
||||
cancelled_year_month as (
|
||||
select d.date, count(distinct b.id_booking) as cancelled_bookings
|
||||
select
|
||||
d.date,
|
||||
'global' as dimension,
|
||||
'global' as dimension_value,
|
||||
count(distinct b.id_booking) as cancelled_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.updated_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.updated_date_utc) <= d.day
|
||||
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
|
||||
group by 1
|
||||
group by 1, 2, 3
|
||||
|
||||
union all
|
||||
|
||||
select
|
||||
d.date,
|
||||
'by_number_of_listings' as dimension,
|
||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
||||
count(distinct b.id_booking) as cancelled_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
on date_trunc('month', b.updated_date_utc)::date = d.first_day_month
|
||||
and extract(day from b.updated_date_utc) <= d.day
|
||||
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
|
||||
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
group by 1, 2, 3
|
||||
),
|
||||
-- Billable Bookings MTD --
|
||||
billable_year_month as (
|
||||
select d.date, count(distinct b.id_booking) as billable_bookings
|
||||
select
|
||||
d.date,
|
||||
'global' as dimension,
|
||||
'global' as dimension_value,
|
||||
count(distinct b.id_booking) as billable_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__booking_charge_events b
|
||||
on date_trunc('month', b.booking_fee_charge_date_utc)::date = d.first_day_month
|
||||
on date_trunc('month', b.booking_fee_charge_date_utc)::date
|
||||
= d.first_day_month
|
||||
and extract(day from b.booking_fee_charge_date_utc) <= d.day
|
||||
group by 1
|
||||
group by 1, 2, 3
|
||||
|
||||
union all
|
||||
|
||||
select
|
||||
d.date,
|
||||
'by_number_of_listings' as dimension,
|
||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
||||
count(distinct bce.id_booking) as billable_bookings
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_core__booking_charge_events bce
|
||||
on date_trunc('month', bce.booking_fee_charge_date_utc)::date
|
||||
= d.first_day_month
|
||||
and extract(day from bce.booking_fee_charge_date_utc) <= d.day
|
||||
inner join int_core__bookings b on b.id_booking = bce.id_booking
|
||||
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
group by 1, 2, 3
|
||||
)
|
||||
|
||||
-- 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,
|
||||
crym.created_bookings,
|
||||
coym.check_out_bookings,
|
||||
caym.cancelled_bookings,
|
||||
biym.billable_bookings
|
||||
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
|
||||
left join cancelled_year_month caym on caym.date = d.date
|
||||
left join billable_year_month biym on biym.date = d.date
|
||||
from int_dates_mtd_by_dimension d
|
||||
left join
|
||||
created_year_month crym
|
||||
on crym.date = d.date
|
||||
and crym.dimension = d.dimension
|
||||
and crym.dimension_value = d.dimension_value
|
||||
left join
|
||||
check_out_year_month coym
|
||||
on coym.date = d.date
|
||||
and coym.dimension = d.dimension
|
||||
and coym.dimension_value = d.dimension_value
|
||||
left join
|
||||
cancelled_year_month caym
|
||||
on caym.date = d.date
|
||||
and caym.dimension = d.dimension
|
||||
and caym.dimension_value = d.dimension_value
|
||||
left join
|
||||
billable_year_month biym
|
||||
on biym.date = d.date
|
||||
and biym.dimension = d.dimension
|
||||
and biym.dimension_value = d.dimension_value
|
||||
|
|
|
|||
|
|
@ -227,13 +227,34 @@ models:
|
|||
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.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- dimension
|
||||
- dimension_value
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date booking-related metrics.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__mtd_guest_journey_metrics
|
||||
description: |
|
||||
|
|
|
|||
38
models/intermediate/cross/int_dates_mtd_by_dimension.sql
Normal file
38
models/intermediate/cross/int_dates_mtd_by_dimension.sql
Normal file
|
|
@ -0,0 +1,38 @@
|
|||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
int_core__mtd_accommodation_segmentation as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }})
|
||||
|
||||
select distinct
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
'global' as dimension,
|
||||
'global' as dimension_value,
|
||||
d.first_day_month,
|
||||
d.last_day_month,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month
|
||||
from int_dates_mtd d
|
||||
|
||||
union all
|
||||
|
||||
select distinct
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
'by_number_of_listings' as dimension,
|
||||
a.active_accommodations_per_deal_segmentation as dimension_value,
|
||||
d.first_day_month,
|
||||
d.last_day_month,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month
|
||||
from int_dates_mtd d
|
||||
inner join int_core__mtd_accommodation_segmentation a
|
||||
on d.date = a.date
|
||||
|
|
@ -6,6 +6,8 @@ previous year for each line & computing relative increment. --
|
|||
with
|
||||
int_core__mtd_booking_metrics as (
|
||||
select * from {{ ref("int_core__mtd_booking_metrics") }}
|
||||
-- TEMPORAL: FORCING DIMENSION = GLOBAL TO AVOID BREAKING CHANGES IN PRODUCTION
|
||||
where dimension = 'global'
|
||||
),
|
||||
int_core__mtd_guest_journey_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
|
||||
|
|
|
|||
|
|
@ -424,5 +424,92 @@ models:
|
|||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: Id of the deal associated to the host.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_dates_mtd_by_dimension
|
||||
description: |
|
||||
This model provides Month-To-Date (MTD) necessary dates, dimension and dimension_values
|
||||
for MTD-based models to work.
|
||||
It provides the basic "empty" structure from which metrics will be built upon. This is, on
|
||||
top of the Date that characterises int_dates_mtd, including the dimensions and their
|
||||
respective values that should appear in any mtd metric model.
|
||||
|
||||
Example:
|
||||
- For the "global" dimension, we will only have the "global" dimension value.
|
||||
- For the "by_number_of_listing" dimension, we will have different values
|
||||
according to the segments defined, ex: 0, 1-5, 6-20, etc.
|
||||
|
||||
... and so on and forth for any available dimension. These combinations should appear
|
||||
for each date of the MTD models.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- dimension
|
||||
- dimension_value
|
||||
|
||||
columns:
|
||||
- name: year
|
||||
data_type: int
|
||||
description: Year number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: month
|
||||
data_type: int
|
||||
description: Month number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: day
|
||||
data_type: int
|
||||
description: Day monthly number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: is_end_of_month
|
||||
data_type: boolean
|
||||
description: Is end of month, 1 for yes, 0 for no.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: is_current_month
|
||||
data_type: boolean
|
||||
description: |
|
||||
Checks if the date is within the current executed month,
|
||||
1 for yes, 0 for no.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: first_day_month
|
||||
data_type: date
|
||||
description: |
|
||||
First day of the month correspoding to the date field.
|
||||
It comes from int_dates_mtd logic.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: date
|
||||
data_type: date
|
||||
description: |
|
||||
Main date for the computation, metrics include monthly information
|
||||
until this date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
Loading…
Add table
Add a link
Reference in a new issue