Merged PR 2858: Split Booking Metrics
# Description This is a pure refactor PR for optimization purposes. The PR splits the model `int_core__mtd_booking_metrics` into four different models, one for each of the metrics that were computed in the old model. The only model that depended on `int_core__mtd_booking_metrics` was `int_mtd_vs_previous_year_metrics`. Now it depends on the four new models instead. # 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: #21438
This commit is contained in:
commit
02520d87ee
7 changed files with 381 additions and 226 deletions
|
|
@ -0,0 +1,58 @@
|
|||
{% set dimensions = get_kpi_dimensions() %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
billable_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(bce.id_booking) as billable_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__bookings") }} b on b.id_booking = bce.id_booking
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__bookings") }} b on b.id_booking = bce.id_booking
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.dimension,
|
||||
d.dimension_value,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
biym.billable_bookings
|
||||
from {{ ref("int_dates_mtd_by_dimension") }} d
|
||||
left join
|
||||
billable_year_month biym
|
||||
on biym.date = d.date
|
||||
and biym.dimension = d.dimension
|
||||
and biym.dimension_value = d.dimension_value
|
||||
|
|
@ -1,201 +0,0 @@
|
|||
/*
|
||||
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"]) }}
|
||||
|
||||
with
|
||||
/*
|
||||
These are the original, raw CTEs for the upstream models used in this model.
|
||||
They were inlined because they were acting as an optimization fence.
|
||||
We will keep them here for a bit as a reference, but we probably want to
|
||||
delete this at some point.
|
||||
|
||||
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
|
||||
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 (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as created_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
),
|
||||
-- Checkout Bookings MTD --
|
||||
check_out_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as check_out_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
),
|
||||
-- Cancelled Bookings MTD --
|
||||
cancelled_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as cancelled_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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") }}
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
),
|
||||
-- Billable Bookings MTD --
|
||||
billable_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(bce.id_booking) as billable_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__bookings") }} b on b.id_booking = bce.id_booking
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__bookings") }} b on b.id_booking = bce.id_booking
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
|
||||
-- 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 {{ ref("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
|
||||
|
|
@ -0,0 +1,54 @@
|
|||
{% set dimensions = get_kpi_dimensions() %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
cancelled_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as cancelled_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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") }}
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.dimension,
|
||||
d.dimension_value,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
caym.cancelled_bookings
|
||||
from {{ ref("int_dates_mtd_by_dimension") }} d
|
||||
left join
|
||||
cancelled_year_month caym
|
||||
on caym.date = d.date
|
||||
and caym.dimension = d.dimension
|
||||
and caym.dimension_value = d.dimension_value
|
||||
|
|
@ -0,0 +1,53 @@
|
|||
{% set dimensions = get_kpi_dimensions() %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
check_out_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as check_out_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.dimension,
|
||||
d.dimension_value,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
coym.check_out_bookings
|
||||
from {{ ref("int_dates_mtd_by_dimension") }} d
|
||||
left join
|
||||
check_out_year_month coym
|
||||
on coym.date = d.date
|
||||
and coym.dimension = d.dimension
|
||||
and coym.dimension_value = d.dimension_value
|
||||
|
|
@ -0,0 +1,53 @@
|
|||
{% set dimensions = get_kpi_dimensions() %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
|
||||
with
|
||||
created_year_month as (
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as created_bookings
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
{{ ref("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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
{{ ref("int_core__mtd_accommodation_segmentation") }} mas
|
||||
on u.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% elif dimension.dimension == "'by_billing_country'" %}
|
||||
inner join
|
||||
{{ ref("int_core__user_host") }} u
|
||||
on b.id_user_host = u.id_user_host
|
||||
and u.main_billing_country_iso_3_per_deal is not null
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
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
|
||||
from {{ ref("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
|
||||
|
|
@ -508,11 +508,123 @@ models:
|
|||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__mtd_booking_metrics
|
||||
- name: int_core__mtd_created_bookings_metric
|
||||
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.
|
||||
This model contains the historic metric of bookings created by date. 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
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
- by_billing_country
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__mtd_check_out_bookings_metric
|
||||
description: |
|
||||
This model contains the historic metric of bookings checking out by date.
|
||||
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
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
- by_billing_country
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__mtd_cancelled_bookings_metric
|
||||
description: |
|
||||
This model contains the historic metric of bookings cancelled by date.
|
||||
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
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
- by_billing_country
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__mtd_billable_bookings_metric
|
||||
description: |
|
||||
This model contains the historic metric of bookings billed by date.
|
||||
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:
|
||||
|
|
|
|||
|
|
@ -2,11 +2,19 @@
|
|||
This model pivots the data of the different mtd metrics models to get
|
||||
previous year for each line & computing relative increment. --
|
||||
*/
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
with
|
||||
int_core__mtd_booking_metrics as (
|
||||
select * from {{ ref("int_core__mtd_booking_metrics") }}
|
||||
int_core__mtd_created_bookings_metric as (
|
||||
select * from {{ ref("int_core__mtd_created_bookings_metric") }}
|
||||
),
|
||||
int_core__mtd_check_out_bookings_metric as (
|
||||
select * from {{ ref("int_core__mtd_check_out_bookings_metric") }}
|
||||
),
|
||||
int_core__mtd_cancelled_bookings_metric as (
|
||||
select * from {{ ref("int_core__mtd_cancelled_bookings_metric") }}
|
||||
),
|
||||
int_core__mtd_billable_bookings_metric as (
|
||||
select * from {{ ref("int_core__mtd_billable_bookings_metric") }}
|
||||
),
|
||||
int_core__mtd_guest_journey_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
|
||||
|
|
@ -23,7 +31,9 @@ with
|
|||
int_xero__mtd_invoicing_metrics as (
|
||||
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||
),
|
||||
int_dates_mtd_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
|
||||
int_dates_mtd_by_dimension as (
|
||||
select * from {{ ref("int_dates_mtd_by_dimension") }}
|
||||
),
|
||||
|
||||
plain_kpi_combination as (
|
||||
|
||||
|
|
@ -39,10 +49,10 @@ with
|
|||
d.dimension_value,
|
||||
|
||||
-- BOOKINGS --
|
||||
bookings.created_bookings,
|
||||
bookings.check_out_bookings,
|
||||
bookings.cancelled_bookings,
|
||||
bookings.billable_bookings,
|
||||
created_bookings.created_bookings,
|
||||
check_out_bookings.check_out_bookings,
|
||||
cancelled_bookings.cancelled_bookings,
|
||||
billable_bookings.billable_bookings,
|
||||
|
||||
-- GUEST JOURNEYS --
|
||||
guest_journeys.created_guest_journeys,
|
||||
|
|
@ -147,8 +157,9 @@ with
|
|||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
)
|
||||
/ nullif(bookings.created_bookings, 0) as total_revenue_per_created_booking,
|
||||
) / nullif(
|
||||
created_bookings.created_bookings, 0
|
||||
) as total_revenue_per_created_booking,
|
||||
(
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||
|
|
@ -175,11 +186,26 @@ with
|
|||
) as total_revenue_per_listings_booked_in_month
|
||||
|
||||
from int_dates_mtd_by_dimension d
|
||||
left join
|
||||
int_core__mtd_booking_metrics bookings
|
||||
on d.date = bookings.date
|
||||
and d.dimension = bookings.dimension
|
||||
and d.dimension_value = bookings.dimension_value
|
||||
left join
|
||||
int_core__mtd_created_bookings_metric created_bookings
|
||||
on d.date = created_bookings.date
|
||||
and d.dimension = created_bookings.dimension
|
||||
and d.dimension_value = created_bookings.dimension_value
|
||||
left join
|
||||
int_core__mtd_check_out_bookings_metric check_out_bookings
|
||||
on d.date = check_out_bookings.date
|
||||
and d.dimension = check_out_bookings.dimension
|
||||
and d.dimension_value = check_out_bookings.dimension_value
|
||||
left join
|
||||
int_core__mtd_cancelled_bookings_metric cancelled_bookings
|
||||
on d.date = cancelled_bookings.date
|
||||
and d.dimension = cancelled_bookings.dimension
|
||||
and d.dimension_value = cancelled_bookings.dimension_value
|
||||
left join
|
||||
int_core__mtd_billable_bookings_metric billable_bookings
|
||||
on d.date = billable_bookings.date
|
||||
and d.dimension = billable_bookings.dimension
|
||||
and d.dimension_value = billable_bookings.dimension_value
|
||||
left join
|
||||
int_core__mtd_guest_journey_metrics guest_journeys
|
||||
on d.date = guest_journeys.date
|
||||
|
|
@ -190,18 +216,18 @@ with
|
|||
on d.date = accommodations.date
|
||||
and d.dimension = accommodations.dimension
|
||||
and d.dimension_value = accommodations.dimension_value
|
||||
left join
|
||||
int_core__mtd_deal_metrics deals
|
||||
left join
|
||||
int_core__mtd_deal_metrics deals
|
||||
on d.date = deals.date
|
||||
and d.dimension = deals.dimension
|
||||
and d.dimension_value = deals.dimension_value
|
||||
left join
|
||||
int_core__mtd_guest_payments_metrics guest_payments
|
||||
int_core__mtd_guest_payments_metrics guest_payments
|
||||
on d.date = guest_payments.date
|
||||
and d.dimension = guest_payments.dimension
|
||||
and d.dimension_value = guest_payments.dimension_value
|
||||
left join
|
||||
int_xero__mtd_invoicing_metrics invoicing
|
||||
left join
|
||||
int_xero__mtd_invoicing_metrics invoicing
|
||||
on d.date = invoicing.date
|
||||
and d.dimension = invoicing.dimension
|
||||
and d.dimension_value = invoicing.dimension_value
|
||||
|
|
@ -308,7 +334,7 @@ select
|
|||
from plain_kpi_combination current
|
||||
left join
|
||||
plain_kpi_combination previous_year
|
||||
on current.dimension = previous_year.dimension
|
||||
on current.dimension = previous_year.dimension
|
||||
and current.dimension_value = previous_year.dimension_value
|
||||
and current.month = previous_year.month
|
||||
and current.year = previous_year.year + 1
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue