Merged PR 3420: Remove previous KPIs computation for Bookings, Guest Journeys and Guest Payments

# Description

Removes old computation of KPIs of Bookings, Guest Journeys and Guest Payments, after yesterday's switch to new computation.

It cleans 1) models 2) schema entries and 3) temporary tests.

# Checklist

- [X] The edited models and dependants run properly with production data.
- [NA] The edited models are sufficiently documented.
- [X] The edited models contain PK tests, and I've ran and passed them. **(Except for the duplicated Booking to Product Bundle)**
- [X] I have checked for DRY opportunities with other models and docs.
- [NA] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Remove previous KPIs computation for Bookings, Guest Journeys and Guest Payments

Related work items: #23576
This commit is contained in:
Oriol Roqué Paniagua 2024-11-05 10:12:00 +00:00
parent f601b69c7d
commit c21b05f9cf
19 changed files with 0 additions and 1658 deletions

View file

@ -1,91 +0,0 @@
/*
This model provides monthly booking metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
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_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
-- Created Bookings by id_deal --
created_year_month as (
select
date_trunc('month', b.created_date_utc)::date as first_day_month,
u.id_deal,
count(distinct b.id_booking) as created_bookings
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where u.id_deal is not null
group by 1, 2
),
-- Checkout Bookings by id_deal --
check_out_year_month as (
select
date_trunc('month', b.check_out_date_utc)::date as first_day_month,
u.id_deal,
count(distinct b.id_booking) as check_out_bookings
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where u.id_deal is not null
group by 1, 2
),
-- Cancelled Bookings by id_deal --
-- Cancellation date equivalent to the last time the cancelled booking was updated
cancelled_year_month as (
select
date_trunc('month', b.updated_date_utc)::date as first_day_month,
u.id_deal,
count(distinct b.id_booking) as cancelled_bookings
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
where
u.id_deal is not null
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
group by 1, 2
),
-- Billable Bookings by id_deal --
billable_year_month as (
select
date_trunc('month', bce.booking_fee_charge_date_utc)::date
as first_day_month,
u.id_deal,
count(distinct bce.id_booking) as billable_bookings
from int_core__unified_user u
inner join int_core__bookings b on u.id_user = b.id_user_host
inner join int_core__booking_charge_events bce on b.id_booking = bce.id_booking
where u.id_deal is not null
group by 1, 2
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_bookings,
biym.billable_bookings
from int_dates_by_deal d
left join
created_year_month crym
on crym.first_day_month = d.first_day_month
and crym.id_deal = d.id_deal
left join
check_out_year_month coym
on coym.first_day_month = d.first_day_month
and coym.id_deal = d.id_deal
left join
cancelled_year_month caym
on caym.first_day_month = d.first_day_month
and caym.id_deal = d.id_deal
left join
billable_year_month biym
on biym.first_day_month = d.first_day_month
and biym.id_deal = d.id_deal

View file

@ -1,112 +0,0 @@
/*
This model provides monthly guest journey metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments", version=2) }}
),
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
first_payment_per_verification_request as (
select
vp.id_verification_request,
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
from int_core__verification_payments vp
where
upper(vp.payment_status) = {{ var("paid_payment_state") }}
and vp.id_verification_request is not null
group by 1
),
-- Created Guest Journeys by id_deal --
created_year_month as (
select
date_trunc('month', vr.created_date_utc)::date as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as created_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1, 2
),
-- Started Guest Journeys by id_deal --
started_year_month as (
select
date_trunc('month', vr.verification_estimated_started_date_utc)::date
as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as started_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1, 2
),
-- Completed Guest Journeys by id_deal --
completed_year_month as (
select
date_trunc('month', vr.verification_estimated_completed_date_utc)::date
as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as completed_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr on u.id_user = vr.id_user_host
where u.id_deal is not null
group by 1, 2
),
-- Paid Guest Journeys MTD --
paid_year_month as (
select
date_trunc('month', p.first_payment_paid_date_utc)::date as first_day_month,
u.id_deal,
count(distinct vr.id_verification_request) as paid_guest_journeys
from int_core__unified_user u
inner join int_core__verification_requests vr on u.id_user = vr.id_user_host
inner join
first_payment_per_verification_request p
on vr.id_verification_request = p.id_verification_request
where u.id_deal is not null
group by 1, 2
)
-- Final aggregation of subqueries + rates computation --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
cym.created_guest_journeys,
sym.started_guest_journeys,
coym.completed_guest_journeys,
pym.paid_guest_journeys,
cast(sym.started_guest_journeys as decimal)
/ cym.created_guest_journeys as start_rate_guest_journey,
cast(coym.completed_guest_journeys as decimal)
/ sym.started_guest_journeys as completion_rate_guest_journey,
1
- cast(coym.completed_guest_journeys as decimal)
/ sym.started_guest_journeys as incompletion_rate_guest_journey,
cast(pym.paid_guest_journeys as decimal)
/ coym.completed_guest_journeys as payment_rate_guest_journey
from int_dates_by_deal d
left join
created_year_month cym
on d.first_day_month = cym.first_day_month
and d.id_deal = cym.id_deal
left join
started_year_month sym
on d.first_day_month = sym.first_day_month
and d.id_deal = sym.id_deal
left join
completed_year_month coym
on d.first_day_month = coym.first_day_month
and d.id_deal = coym.id_deal
left join
paid_year_month pym
on d.first_day_month = pym.first_day_month
and d.id_deal = pym.id_deal

View file

@ -1,83 +0,0 @@
/*
This model provides monthly guest revenue metrics for those hosts that have a deal assigned.
*/
{% set deposit_fees_verification_payment_type_items = "('FEE')" %}
{% set waiver_fees_verification_payment_type_items = "('WAIVER')" %}
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments", version=2) }}
),
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
-- Paid Guest Revenue by id_deal --
guest_payments_year_month as (
select
date_trunc('month', vp.payment_paid_date_utc)::date as first_day_month,
u.id_deal,
sum(
case
when
upper(vp.verification_payment_type)
in {{ deposit_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as deposit_fees_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ waiver_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as waiver_payments_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ checkin_cover_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as checkin_cover_fees_in_gbp
from int_core__verification_payments vp
inner join
int_core__verification_requests vr
on vp.id_verification_request = vr.id_verification_request
inner join int_core__unified_user u on u.id_user = vr.id_user_host
where
upper(vp.payment_status) = {{ var("paid_payment_state") }}
and u.id_deal is not null
group by 1, 2
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
nullif(gpym.deposit_fees_in_gbp, 0) as deposit_fees_in_gbp,
nullif(gpym.waiver_payments_in_gbp, 0) as waiver_payments_in_gbp,
nullif(gpym.checkin_cover_fees_in_gbp, 0) as checkin_cover_fees_in_gbp,
nullif(
coalesce(gpym.deposit_fees_in_gbp, 0)
+ coalesce(gpym.waiver_payments_in_gbp, 0)
+ coalesce(gpym.checkin_cover_fees_in_gbp, 0),
0
) as total_guest_payments_in_gbp
from int_dates_by_deal d
left join
guest_payments_year_month gpym
on d.first_day_month = gpym.first_day_month
and d.id_deal = gpym.id_deal

View file

@ -1,58 +0,0 @@
{% 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

View file

@ -1,54 +0,0 @@
{% 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

View file

@ -1,53 +0,0 @@
{% 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

View file

@ -1,53 +0,0 @@
{% 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

View file

@ -1,215 +0,0 @@
/*
This model provides Month-To-Date (MTD) based on Guest Journey metrics.
*/
{% set dimensions = get_kpi_dimensions() %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments", version=2) }}
),
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_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
int_dates_mtd_by_dimension as (
select * from {{ ref("int_dates_mtd_by_dimension") }}
),
first_payment_per_verification_request as (
select
vp.id_verification_request,
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
from int_core__verification_payments vp
where
upper(vp.payment_status) = {{ var("paid_payment_state") }}
and vp.id_verification_request is not null
group by 1
),
-- Created Guest Journeys MTD --
created_year_month as (
{% for dimension in dimensions %}
select
d.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(distinct vr.id_verification_request) as created_guest_journeys
from int_dates_mtd d
inner join
int_core__verification_requests vr
on date_trunc('month', vr.created_date_utc)::date = d.first_day_month
and extract(day from vr.created_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.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
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__user_host u
on vr.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 %}
),
-- Started Guest Journeys MTD --
started_year_month as (
{% for dimension in dimensions %}
select
d.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(distinct vr.id_verification_request) as started_guest_journeys
from int_dates_mtd d
inner join
int_core__verification_requests vr
on date_trunc('month', vr.verification_estimated_started_date_utc)::date
= d.first_day_month
and extract(day from vr.verification_estimated_started_date_utc)
<= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.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
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__user_host u
on vr.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 %}
),
-- Completed Guest Journeys MTD --
completed_year_month as (
{% for dimension in dimensions %}
select
d.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(distinct vr.id_verification_request) as completed_guest_journeys
from int_dates_mtd d
inner join
int_core__verification_requests vr
on date_trunc(
'month', vr.verification_estimated_completed_date_utc
)::date
= d.first_day_month
and extract(day from vr.verification_estimated_completed_date_utc)
<= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vr.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
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__user_host u
on vr.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 %}
),
-- Paid Guest Journeys MTD --
paid_year_month as (
{% for dimension in dimensions %}
select
d.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(distinct p.id_verification_request) as paid_guest_journeys
from int_dates_mtd d
inner join
first_payment_per_verification_request p
on date_trunc('month', p.first_payment_paid_date_utc)::date
= d.first_day_month
and extract(day from p.first_payment_paid_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join
int_core__verification_requests vr
on vr.id_verification_request = p.id_verification_request
inner join int_core__user_host u on vr.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
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__verification_requests vr
on vr.id_verification_request = p.id_verification_request
inner join
int_core__user_host u
on vr.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 + rates computation --
select
d.year,
d.month,
d.day,
d.date,
d.dimension,
d.dimension_value,
d.is_end_of_month,
d.is_current_month,
cym.created_guest_journeys,
sym.started_guest_journeys,
coym.completed_guest_journeys,
pym.paid_guest_journeys,
cast(sym.started_guest_journeys as decimal)
/ cym.created_guest_journeys as start_rate_guest_journey,
cast(coym.completed_guest_journeys as decimal)
/ sym.started_guest_journeys as completion_rate_guest_journey,
1
- cast(coym.completed_guest_journeys as decimal)
/ sym.started_guest_journeys as incompletion_rate_guest_journey,
cast(pym.paid_guest_journeys as decimal)
/ coym.completed_guest_journeys as payment_rate_guest_journey
from int_dates_mtd_by_dimension d
left join
created_year_month cym
on cym.date = d.date
and cym.dimension = d.dimension
and cym.dimension_value = d.dimension_value
left join
started_year_month sym
on d.date = sym.date
and d.dimension = sym.dimension
and d.dimension_value = sym.dimension_value
left join
completed_year_month coym
on d.date = coym.date
and d.dimension = coym.dimension
and d.dimension_value = coym.dimension_value
left join
paid_year_month pym
on d.date = pym.date
and d.dimension = pym.dimension
and d.dimension_value = pym.dimension_value

View file

@ -1,111 +0,0 @@
/*
This model provides Month-To-Date (MTD) based on Guest Revenue metrics.
*/
{% set dimensions = get_kpi_dimensions() %}
{% set deposit_fees_verification_payment_type_items = "('FEE')" %}
{% set waiver_fees_verification_payment_type_items = "('WAIVER')" %}
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_core__verification_payments as (
select * from {{ ref("int_core__verification_payments", version=2) }}
),
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
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_dates_mtd_by_dimension as (
select * from {{ ref("int_dates_mtd_by_dimension") }}
),
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
-- Paid Guest Revenue MTD --
guest_payments_year_month as (
{% for dimension in dimensions %}
select
d.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
sum(
case
when
upper(vp.verification_payment_type)
in {{ deposit_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as deposit_fees_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ waiver_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as waiver_payments_in_gbp,
sum(
case
when
upper(vp.verification_payment_type)
in {{ checkin_cover_fees_verification_payment_type_items }}
then vp.amount_without_taxes_in_gbp
else null
end
) as checkin_cover_fees_in_gbp
from int_dates_mtd d
inner join
int_core__verification_payments vp
on date_trunc('month', vp.payment_paid_date_utc)::date
= d.first_day_month
and extract(day from vp.payment_paid_date_utc) <= d.day
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join int_core__user_host u on vp.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
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__user_host u
on vp.id_user_host = u.id_user_host
and u.main_billing_country_iso_3_per_deal is not null
{% endif %}
where upper(vp.payment_status) = {{ var("paid_payment_state") }}
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,
nullif(gpym.deposit_fees_in_gbp, 0) as deposit_fees_in_gbp,
nullif(gpym.waiver_payments_in_gbp, 0) as waiver_payments_in_gbp,
nullif(gpym.checkin_cover_fees_in_gbp, 0) as checkin_cover_fees_in_gbp,
nullif(
coalesce(gpym.deposit_fees_in_gbp, 0)
+ coalesce(gpym.waiver_payments_in_gbp, 0)
+ coalesce(gpym.checkin_cover_fees_in_gbp, 0),
0
) as total_guest_payments_in_gbp
from int_dates_mtd_by_dimension d
left join
guest_payments_year_month gpym
on gpym.date = d.date
and gpym.dimension = d.dimension
and gpym.dimension_value = d.dimension_value

View file

@ -463,252 +463,6 @@ models:
tests: tests:
- not_null - not_null
- name: int_core__monthly_booking_history_by_deal
description: |
This model contains the historic information regarding the bookings for each deal id.
It's used for the business KPIs in the view by deal id. Data is aggregated at the last
day of the month, or up to yesterday if it's the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
deprecation_date: 2024-11-30
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic booking metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null
- name: int_core__monthly_guest_journey_history_by_deal
description: |
This model contains the historic information regarding the guest journey for each deal id.
It's used for the business KPIs in the view by deal id. Data is aggregated at the last
day of the month, or up to yesterday if it's the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
deprecation_date: 2024-11-30
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic guest journey metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null
- name: int_core__mtd_created_bookings_metric
description: |
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.
deprecation_date: 2024-11-30
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.
deprecation_date: 2024-11-30
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.
deprecation_date: 2024-11-30
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.
deprecation_date: 2024-11-30
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_guest_journey_metrics
description: |
This model contains the historic information regarding the guest journeys 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.
deprecation_date: 2024-11-30
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 guest journey-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_accommodation_metrics - name: int_core__mtd_accommodation_metrics
description: | description: |
This model contains the historic information regarding the accommodations in an aggregated manner. This model contains the historic information regarding the accommodations in an aggregated manner.
@ -747,70 +501,6 @@ models:
tests: tests:
- not_null - not_null
- name: int_core__mtd_guest_payments_metrics
description: |
This model contains the historic information regarding the guest payments 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.
deprecation_date: 2024-11-30
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 guest payments-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__monthly_guest_payments_history_by_deal
description: |
This model contains the historic information regarding the guest revenue for each deal id.
It's used for the business KPIs in the view by deal id. Data is aggregated at the last
day of the month, or up to yesterday if it's the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
deprecation_date: 2024-11-30
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic guest revenue metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null
- name: int_core__verification_request_completeness - name: int_core__verification_request_completeness
description: | description: |
The `int_core__verification_request_completeness` model allows to determine if a verification request is The `int_core__verification_request_completeness` model allows to determine if a verification request is

View file

@ -1,52 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_billable_bookings as (
select end_date as date, dimension, dimension_value, billable_bookings
from {{ ref("int_kpis__aggregated_mtd_billable_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_billable_bookings as (
select end_date as date, dimension, dimension_value, billable_bookings
from {{ ref("int_kpis__aggregated_monthly_billable_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_billable_bookings as (
select *
from new_mtd_billable_bookings
union all
select *
from new_monthly_billable_bookings
),
old_billable_bookings as (
select date, dimension, dimension_value, billable_bookings
from {{ ref("int_core__mtd_billable_bookings_metric") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.billable_bookings as old_billable_bookings,
n.billable_bookings as new_billable_bookings,
coalesce(o.billable_bookings, 0) - coalesce(n.billable_bookings, 0) as diff
from old_billable_bookings o
full outer join
new_billable_bookings n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,53 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_cancelled_bookings as (
select end_date as date, dimension, dimension_value, cancelled_bookings
from {{ ref("int_kpis__aggregated_mtd_cancelled_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_cancelled_bookings as (
select end_date as date, dimension, dimension_value, cancelled_bookings
from {{ ref("int_kpis__aggregated_monthly_cancelled_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_cancelled_bookings as (
select *
from new_mtd_cancelled_bookings
union all
select *
from new_monthly_cancelled_bookings
),
old_cancelled_bookings as (
select date, dimension, dimension_value, cancelled_bookings
from {{ ref("int_core__mtd_cancelled_bookings_metric") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.cancelled_bookings as old_cancelled_bookings,
n.cancelled_bookings as new_cancelled_bookings,
coalesce(o.cancelled_bookings, 0)
- coalesce(n.cancelled_bookings, 0) as diff
from old_cancelled_bookings o
full outer join
new_cancelled_bookings n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,53 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_check_out_bookings as (
select end_date as date, dimension, dimension_value, check_out_bookings
from {{ ref("int_kpis__aggregated_mtd_check_out_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_check_out_bookings as (
select end_date as date, dimension, dimension_value, check_out_bookings
from {{ ref("int_kpis__aggregated_monthly_check_out_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_check_out_bookings as (
select *
from new_mtd_check_out_bookings
union all
select *
from new_monthly_check_out_bookings
),
old_check_out_bookings as (
select date, dimension, dimension_value, check_out_bookings
from {{ ref("int_core__mtd_check_out_bookings_metric") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.check_out_bookings as old_check_out_bookings,
n.check_out_bookings as new_check_out_bookings,
coalesce(o.check_out_bookings, 0)
- coalesce(n.check_out_bookings, 0) as diff
from old_check_out_bookings o
full outer join
new_check_out_bookings n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,53 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_completed_guest_journeys as (
select end_date as date, dimension, dimension_value, completed_guest_journeys
from {{ ref("int_kpis__aggregated_mtd_completed_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_completed_guest_journeys as (
select end_date as date, dimension, dimension_value, completed_guest_journeys
from {{ ref("int_kpis__aggregated_monthly_completed_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_completed_guest_journeys as (
select *
from new_mtd_completed_guest_journeys
union all
select *
from new_monthly_completed_guest_journeys
),
old_completed_guest_journeys as (
select date, dimension, dimension_value, completed_guest_journeys
from {{ ref("int_core__mtd_guest_journey_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.completed_guest_journeys as old_completed_guest_journeys,
n.completed_guest_journeys as new_completed_guest_journeys,
coalesce(o.completed_guest_journeys, 0)
- coalesce(n.completed_guest_journeys, 0) as diff
from old_completed_guest_journeys o
full outer join
new_completed_guest_journeys n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,52 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_created_bookings as (
select end_date as date, dimension, dimension_value, created_bookings
from {{ ref("int_kpis__aggregated_mtd_created_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_created_bookings as (
select end_date as date, dimension, dimension_value, created_bookings
from {{ ref("int_kpis__aggregated_monthly_created_bookings") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_created_bookings as (
select *
from new_mtd_created_bookings
union all
select *
from new_monthly_created_bookings
),
old_created_bookings as (
select date, dimension, dimension_value, created_bookings
from {{ ref("int_core__mtd_created_bookings_metric") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.created_bookings as old_created_bookings,
n.created_bookings as new_created_bookings,
coalesce(o.created_bookings, 0) - coalesce(n.created_bookings, 0) as diff
from old_created_bookings o
full outer join
new_created_bookings n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,53 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_created_guest_journeys as (
select end_date as date, dimension, dimension_value, created_guest_journeys
from {{ ref("int_kpis__aggregated_mtd_created_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_created_guest_journeys as (
select end_date as date, dimension, dimension_value, created_guest_journeys
from {{ ref("int_kpis__aggregated_monthly_created_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_created_guest_journeys as (
select *
from new_mtd_created_guest_journeys
union all
select *
from new_monthly_created_guest_journeys
),
old_created_guest_journeys as (
select date, dimension, dimension_value, created_guest_journeys
from {{ ref("int_core__mtd_guest_journey_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.created_guest_journeys as old_created_guest_journeys,
n.created_guest_journeys as new_created_guest_journeys,
coalesce(o.created_guest_journeys, 0)
- coalesce(n.created_guest_journeys, 0) as diff
from old_created_guest_journeys o
full outer join
new_created_guest_journeys n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,57 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_guest_journeys_with_payment as (
select end_date as date, dimension, dimension_value, guest_journeys_with_payment
from {{ ref("int_kpis__aggregated_mtd_guest_journeys_with_payment") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_guest_journeys_with_payment as (
select end_date as date, dimension, dimension_value, guest_journeys_with_payment
from {{ ref("int_kpis__aggregated_monthly_guest_journeys_with_payment") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_guest_journeys_with_payment as (
select *
from new_mtd_guest_journeys_with_payment
union all
select *
from new_monthly_guest_journeys_with_payment
),
old_guest_journeys_with_payment as (
select
date,
dimension,
dimension_value,
paid_guest_journeys as guest_journeys_with_payment
from {{ ref("int_core__mtd_guest_journey_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.guest_journeys_with_payment as old_guest_journeys_with_payment,
n.guest_journeys_with_payment as new_guest_journeys_with_payment,
coalesce(o.guest_journeys_with_payment, 0)
- coalesce(n.guest_journeys_with_payment, 0) as diff
from old_guest_journeys_with_payment o
full outer join
new_guest_journeys_with_payment n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc

View file

@ -1,92 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_guest_payments as (
select
end_date as date,
dimension,
dimension_value,
deposit_fees_in_gbp,
waiver_payments_in_gbp,
checkin_cover_fees_in_gbp,
total_guest_payments_in_gbp
from {{ ref("int_kpis__aggregated_mtd_guest_payments") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_guest_payments as (
select
end_date as date,
dimension,
dimension_value,
deposit_fees_in_gbp,
waiver_payments_in_gbp,
checkin_cover_fees_in_gbp,
total_guest_payments_in_gbp
from {{ ref("int_kpis__aggregated_monthly_guest_payments") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_guest_payments as (
select *
from new_mtd_guest_payments
union all
select *
from new_monthly_guest_payments
),
old_guest_payments as (
select
date,
dimension,
dimension_value,
deposit_fees_in_gbp,
waiver_payments_in_gbp,
checkin_cover_fees_in_gbp,
total_guest_payments_in_gbp
from {{ ref("int_core__mtd_guest_payments_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.deposit_fees_in_gbp as old_deposit_fees_in_gbp,
n.deposit_fees_in_gbp as new_deposit_fees_in_gbp,
coalesce(o.deposit_fees_in_gbp, 0)
- coalesce(n.deposit_fees_in_gbp, 0) as diff_deposit_fees_in_gbp,
o.waiver_payments_in_gbp as old_waiver_payments_in_gbp,
n.waiver_payments_in_gbp as new_waiver_payments_in_gbp,
coalesce(o.waiver_payments_in_gbp, 0)
- coalesce(n.waiver_payments_in_gbp, 0) as diff_waiver_payments_in_gbp,
o.checkin_cover_fees_in_gbp as old_checkin_cover_fees_in_gbp,
n.checkin_cover_fees_in_gbp as new_checkin_cover_fees_in_gbp,
coalesce(o.checkin_cover_fees_in_gbp, 0) - coalesce(
n.checkin_cover_fees_in_gbp, 0
) as diff_checkin_cover_fees_in_gbp,
o.total_guest_payments_in_gbp as old_total_guest_payments_in_gbp,
n.total_guest_payments_in_gbp as new_total_guest_payments_in_gbp,
coalesce(o.total_guest_payments_in_gbp, 0) - coalesce(
n.total_guest_payments_in_gbp, 0
) as diff_total_guest_payments_in_gbp
from old_guest_payments o
full outer join
new_guest_payments n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where
diff_deposit_fees_in_gbp <> 0
or diff_waiver_payments_in_gbp <> 0
or diff_checkin_cover_fees_in_gbp <> 0
or diff_total_guest_payments_in_gbp <> 0
order by date desc, diff_total_guest_payments_in_gbp desc

View file

@ -1,53 +0,0 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_started_guest_journeys as (
select end_date as date, dimension, dimension_value, started_guest_journeys
from {{ ref("int_kpis__aggregated_mtd_started_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_started_guest_journeys as (
select end_date as date, dimension, dimension_value, started_guest_journeys
from {{ ref("int_kpis__aggregated_monthly_started_guest_journeys") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_started_guest_journeys as (
select *
from new_mtd_started_guest_journeys
union all
select *
from new_monthly_started_guest_journeys
),
old_started_guest_journeys as (
select date, dimension, dimension_value, started_guest_journeys
from {{ ref("int_core__mtd_guest_journey_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.started_guest_journeys as old_started_guest_journeys,
n.started_guest_journeys as new_started_guest_journeys,
coalesce(o.started_guest_journeys, 0)
- coalesce(n.started_guest_journeys, 0) as diff
from old_started_guest_journeys o
full outer join
new_started_guest_journeys n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc