create individual models for each booking metric
This commit is contained in:
parent
cf1d6e28cc
commit
4140f5b917
4 changed files with 219 additions and 0 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
|
||||||
|
|
@ -0,0 +1,55 @@
|
||||||
|
{% set dimensions = get_kpi_dimensions() %}
|
||||||
|
|
||||||
|
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||||
|
|
||||||
|
with
|
||||||
|
-- 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 %}
|
||||||
|
)
|
||||||
|
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
|
||||||
Loading…
Add table
Add a link
Reference in a new issue