Merged PR 2774: Inline CTEs on int_core__mtd_booking_metrics
# Description This PR is a pure refactor (as in, doesn't change the output of the model at all). The only purpose of the changes in this PR is to improve the performance on the model. The strategy to achieve this has been to inline the basic CTEs of the model (inline=replace references to the CTE with direct `ref` inside the model). This works because it breaks an optimization fence. # 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: #20835
This commit is contained in:
commit
2733adfd31
1 changed files with 40 additions and 25 deletions
|
|
@ -7,6 +7,12 @@ This model provides Month-To-Date (MTD) based on Booking metrics.
|
|||
{{ 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 (
|
||||
|
|
@ -18,8 +24,7 @@ with
|
|||
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 %}
|
||||
|
|
@ -28,20 +33,22 @@ with
|
|||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as created_bookings
|
||||
from int_dates_mtd d
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
{{ 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 int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
{{ 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
|
||||
int_core__user_host u
|
||||
{{ 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 %}
|
||||
|
|
@ -59,20 +66,22 @@ with
|
|||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as check_out_bookings
|
||||
from int_dates_mtd d
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
{{ 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 int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
{{ 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
|
||||
int_core__user_host u
|
||||
{{ 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 %}
|
||||
|
|
@ -90,21 +99,23 @@ with
|
|||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(b.id_booking) as cancelled_bookings
|
||||
from int_dates_mtd d
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
int_core__bookings b
|
||||
{{ 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 int_core__user_host u on b.id_user_host = u.id_user_host
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
{{ 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
|
||||
int_core__user_host u
|
||||
{{ 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 %}
|
||||
|
|
@ -122,23 +133,27 @@ with
|
|||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
count(bce.id_booking) as billable_bookings
|
||||
from int_dates_mtd d
|
||||
from {{ ref("int_dates_mtd") }} d
|
||||
inner join
|
||||
int_core__booking_charge_events bce
|
||||
{{ 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 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
|
||||
{{ 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 int_core__bookings b on b.id_booking = bce.id_booking
|
||||
inner join
|
||||
int_core__user_host u
|
||||
{{ 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 %}
|
||||
|
|
@ -163,7 +178,7 @@ select
|
|||
coym.check_out_bookings,
|
||||
caym.cancelled_bookings,
|
||||
biym.billable_bookings
|
||||
from int_dates_mtd_by_dimension d
|
||||
from {{ ref("int_dates_mtd_by_dimension") }} d
|
||||
left join
|
||||
created_year_month crym
|
||||
on crym.date = d.date
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue