Merged PR 2301: KPIs Billable Bookings 1st version

This PR computes KPIs for Billable Bookings for both views (Global, by deal id)
It's the 1st version, mainly because numbers are not fully in-line with Jamie's export and I'd like to understand why. It uses booking_charge_events, as suggested by Pablo. In the meantime, I'm debugging the differences based on the invoicing export tool that provides Finance first rough numbers before amendment.

In any case, it can be used for a first rough idea.

Related work items: #18111
This commit is contained in:
Oriol Roqué Paniagua 2024-07-15 10:59:37 +00:00
parent bf473ab971
commit 0ac9f479da
2 changed files with 34 additions and 2 deletions

View file

@ -6,6 +6,7 @@ This model provides monthly booking metrics for those hosts that have a deal ass
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") }}),
@ -46,6 +47,20 @@ with
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
@ -56,7 +71,8 @@ with
d.id_deal,
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_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
@ -67,3 +83,6 @@ with
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

@ -5,6 +5,7 @@ This model provides Month-To-Date (MTD) based on Booking metrics.
{{ config(materialized="table", unique_key="date") }}
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_mtd as (select * from {{ ref("int_dates_mtd") }}),
-- Created Bookings MTD --
@ -38,6 +39,16 @@ with
and extract(day from b.updated_date_utc) <= d.day
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
group by 1
),
-- Billable Bookings MTD --
billable_year_month as (
select d.date, count(distinct b.id_booking) as billable_bookings
from int_dates_mtd d
inner join
int_core__booking_charge_events b
on date_trunc('month', b.booking_fee_charge_date_utc)::date = d.first_day_month
and extract(day from b.booking_fee_charge_date_utc) <= d.day
group by 1
)
-- Final aggregation of subqueries --
select
@ -49,8 +60,10 @@ select
d.is_current_month,
crym.created_bookings,
coym.check_out_bookings,
caym.cancelled_bookings
caym.cancelled_bookings,
biym.billable_bookings
from int_dates_mtd d
left join created_year_month crym on crym.date = d.date
left join check_out_year_month coym on coym.date = d.date
left join cancelled_year_month caym on caym.date = d.date
left join billable_year_month biym on biym.date = d.date