Merged PR 2522: Don't Repeat Yourself for KPIs - Applied to Bookings
# Description What's new: - Creation of `get_kpi_dimensions`: new macro to have a single point of source of configuration for dimensions for the KPIs. It's a way to enforce global variables on-demand. I kind of like this approach and we could do it for Xero models as well :) - Modification of `int_core__mtd_booking_metrics` and `int_dates_mtd_by_dimension`: removal of duplicated code within the dimension context. Uses Jinja code and applies different configurations depending on the dimension chosen. Still, different metrics are placed in different CTEs. I believe it might be possible to also configure metrics BUT at the cost of over-complexifying the macro logic, so I wouldn't go for it at this stage. # 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: #19325
This commit is contained in:
parent
90a7ad5eea
commit
b61fe3f70d
3 changed files with 127 additions and 156 deletions
13
macros/get_kpi_dimensions.sql
Normal file
13
macros/get_kpi_dimensions.sql
Normal file
|
|
@ -0,0 +1,13 @@
|
||||||
|
/*
|
||||||
|
Provides a general configuration for the Dimensions available for the KPIs.
|
||||||
|
Please note that strings should be encoded with " ' your_value_here ' ",
|
||||||
|
while fields from tables should be specified like " your_field_here "
|
||||||
|
*/
|
||||||
|
|
||||||
|
{% macro get_kpi_dimensions() %}
|
||||||
|
{% set dimensions = [
|
||||||
|
{"dimension": "'global'", "dimension_value": "'global'"},
|
||||||
|
{"dimension": "'by_number_of_listings'", "dimension_value": "active_accommodations_per_deal_segmentation"}
|
||||||
|
] %}
|
||||||
|
{{ return(dimensions) }}
|
||||||
|
{% endmacro %}
|
||||||
|
|
@ -2,6 +2,9 @@
|
||||||
This model provides Month-To-Date (MTD) based on Booking metrics.
|
This model provides Month-To-Date (MTD) based on Booking metrics.
|
||||||
|
|
||||||
*/
|
*/
|
||||||
|
|
||||||
|
{% set dimensions = get_kpi_dimensions() %}
|
||||||
|
|
||||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||||
|
|
||||||
with
|
with
|
||||||
|
|
@ -18,141 +21,102 @@ with
|
||||||
|
|
||||||
-- Created Bookings MTD --
|
-- Created Bookings MTD --
|
||||||
created_year_month as (
|
created_year_month as (
|
||||||
select
|
{% for dimension in dimensions %}
|
||||||
d.date,
|
select
|
||||||
'global' as dimension,
|
d.date,
|
||||||
'global' as dimension_value,
|
{{ dimension.dimension }} as dimension,
|
||||||
count(distinct b.id_booking) as created_bookings
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
from int_dates_mtd d
|
count(distinct b.id_booking) as created_bookings
|
||||||
inner join
|
from int_dates_mtd d
|
||||||
int_core__bookings b
|
inner join int_core__bookings b
|
||||||
on date_trunc('month', b.created_date_utc)::date = d.first_day_month
|
on date_trunc('month', b.created_date_utc)::date = d.first_day_month
|
||||||
and extract(day from b.created_date_utc) <= d.day
|
and extract(day from b.created_date_utc) <= d.day
|
||||||
group by 1, 2, 3
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||||
|
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||||
union all
|
inner join int_core__mtd_accommodation_segmentation mas
|
||||||
|
on u.id_deal = mas.id_deal
|
||||||
select
|
and d.date = mas.date
|
||||||
d.date,
|
{% endif %}
|
||||||
'by_number_of_listings' as dimension,
|
group by 1, 2, 3
|
||||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
{% if not loop.last %}
|
||||||
count(distinct b.id_booking) as created_bookings
|
union all
|
||||||
from int_dates_mtd d
|
{% endif %}
|
||||||
inner join
|
{% endfor %}
|
||||||
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 --
|
-- Checkout Bookings MTD --
|
||||||
check_out_year_month as (
|
check_out_year_month as (
|
||||||
select
|
{% for dimension in dimensions %}
|
||||||
d.date,
|
select
|
||||||
'global' as dimension,
|
d.date,
|
||||||
'global' as dimension_value,
|
{{ dimension.dimension }} as dimension,
|
||||||
count(distinct b.id_booking) as check_out_bookings
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
from int_dates_mtd d
|
count(distinct b.id_booking) as check_out_bookings
|
||||||
inner join
|
from int_dates_mtd d
|
||||||
int_core__bookings b
|
inner join int_core__bookings b
|
||||||
on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month
|
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
|
and extract(day from b.check_out_date_utc) <= d.day
|
||||||
group by 1, 2, 3
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||||
|
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||||
union all
|
inner join int_core__mtd_accommodation_segmentation mas
|
||||||
|
on u.id_deal = mas.id_deal
|
||||||
select
|
and d.date = mas.date
|
||||||
d.date,
|
{% endif %}
|
||||||
'by_number_of_listings' as dimension,
|
group by 1, 2, 3
|
||||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
{% if not loop.last %}
|
||||||
count(distinct b.id_booking) as check_out_bookings
|
union all
|
||||||
from int_dates_mtd d
|
{% endif %}
|
||||||
inner join
|
{% endfor %}
|
||||||
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 --
|
-- Cancelled Bookings MTD --
|
||||||
cancelled_year_month as (
|
cancelled_year_month as (
|
||||||
select
|
{% for dimension in dimensions %}
|
||||||
d.date,
|
select
|
||||||
'global' as dimension,
|
d.date,
|
||||||
'global' as dimension_value,
|
{{ dimension.dimension }} as dimension,
|
||||||
count(distinct b.id_booking) as cancelled_bookings
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
from int_dates_mtd d
|
count(distinct b.id_booking) as cancelled_bookings
|
||||||
inner join
|
from int_dates_mtd d
|
||||||
int_core__bookings b
|
inner join int_core__bookings b
|
||||||
on date_trunc('month', b.updated_date_utc)::date = d.first_day_month
|
on date_trunc('month', b.updated_date_utc)::date = d.first_day_month
|
||||||
and extract(day from b.updated_date_utc) <= d.day
|
and extract(day from b.updated_date_utc) <= d.day
|
||||||
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
|
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
|
||||||
group by 1, 2, 3
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||||
|
inner join int_core__user_host u on b.id_user_host = u.id_user_host
|
||||||
union all
|
inner join int_core__mtd_accommodation_segmentation mas
|
||||||
|
on u.id_deal = mas.id_deal
|
||||||
select
|
and d.date = mas.date
|
||||||
d.date,
|
{% endif %}
|
||||||
'by_number_of_listings' as dimension,
|
group by 1, 2, 3
|
||||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
{% if not loop.last %}
|
||||||
count(distinct b.id_booking) as cancelled_bookings
|
union all
|
||||||
from int_dates_mtd d
|
{% endif %}
|
||||||
inner join
|
{% endfor %}
|
||||||
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 Bookings MTD --
|
||||||
billable_year_month as (
|
billable_year_month as (
|
||||||
select
|
{% for dimension in dimensions %}
|
||||||
d.date,
|
select
|
||||||
'global' as dimension,
|
d.date,
|
||||||
'global' as dimension_value,
|
{{ dimension.dimension }} as dimension,
|
||||||
count(distinct b.id_booking) as billable_bookings
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
from int_dates_mtd d
|
count(distinct bce.id_booking) as billable_bookings
|
||||||
inner join
|
from int_dates_mtd d
|
||||||
int_core__booking_charge_events b
|
inner join int_core__booking_charge_events bce
|
||||||
on date_trunc('month', b.booking_fee_charge_date_utc)::date
|
on date_trunc('month', bce.booking_fee_charge_date_utc)::date = d.first_day_month
|
||||||
= d.first_day_month
|
and extract(day from bce.booking_fee_charge_date_utc) <= d.day
|
||||||
and extract(day from b.booking_fee_charge_date_utc) <= d.day
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||||
group by 1, 2, 3
|
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
|
||||||
union all
|
inner join
|
||||||
|
int_core__mtd_accommodation_segmentation mas
|
||||||
select
|
on u.id_deal = mas.id_deal
|
||||||
d.date,
|
and d.date = mas.date
|
||||||
'by_number_of_listings' as dimension,
|
{% endif %}
|
||||||
mas.active_accommodations_per_deal_segmentation as dimension_value,
|
group by 1, 2, 3
|
||||||
count(distinct bce.id_booking) as billable_bookings
|
{% if not loop.last %}
|
||||||
from int_dates_mtd d
|
union all
|
||||||
inner join
|
{% endif %}
|
||||||
int_core__booking_charge_events bce
|
{% endfor %}
|
||||||
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 --
|
-- Final aggregation of subqueries --
|
||||||
|
|
@ -189,4 +153,4 @@ left join
|
||||||
billable_year_month biym
|
billable_year_month biym
|
||||||
on biym.date = d.date
|
on biym.date = d.date
|
||||||
and biym.dimension = d.dimension
|
and biym.dimension = d.dimension
|
||||||
and biym.dimension_value = d.dimension_value
|
and biym.dimension_value = d.dimension_value
|
||||||
|
|
@ -1,4 +1,6 @@
|
||||||
|
|
||||||
|
{% set dimensions = get_kpi_dimensions() %}
|
||||||
|
|
||||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||||
|
|
||||||
with
|
with
|
||||||
|
|
@ -7,32 +9,24 @@ with
|
||||||
),
|
),
|
||||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }})
|
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }})
|
||||||
|
|
||||||
select distinct
|
{% for dimension in dimensions %}
|
||||||
d.year,
|
select distinct
|
||||||
d.month,
|
d.year,
|
||||||
d.day,
|
d.month,
|
||||||
d.date,
|
d.day,
|
||||||
'global' as dimension,
|
d.date,
|
||||||
'global' as dimension_value,
|
{{ dimension.dimension }} as dimension,
|
||||||
d.first_day_month,
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
d.last_day_month,
|
d.first_day_month,
|
||||||
d.is_end_of_month,
|
d.last_day_month,
|
||||||
d.is_current_month
|
d.is_end_of_month,
|
||||||
from int_dates_mtd d
|
d.is_current_month
|
||||||
|
from int_dates_mtd d
|
||||||
union all
|
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||||
|
inner join int_core__mtd_accommodation_segmentation a
|
||||||
select distinct
|
on d.date = a.date
|
||||||
d.year,
|
{% endif %}
|
||||||
d.month,
|
{% if not loop.last %}
|
||||||
d.day,
|
union all
|
||||||
d.date,
|
{% endif %}
|
||||||
'by_number_of_listings' as dimension,
|
{% endfor %}
|
||||||
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
|
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue