Merged PR 3638: Propagates billing info to booking service detail and booking summary

# Description

Changes:
* Handles conversion to GBP directly in the models `int_core__product_service_billing_item` and `int_core__protection_plan_billing_item` .
* Adds the newly created field of `is_missing_id_deal` in `int_core__booking_to_service`, to avoid manually computing downstream.
* Computes total price per service in `int_core__booking_service_detail`. Since, technically, the same service can have different billing lines, I also retrieve some min/max charge dates and some booleans to help the identification.
* Computes total price per booking in `int_core__booking_summary`. Since, technically, the same booking can have different services charged in different moments in time, I also retrieve some min/max charge dates. I also computed a very necessary `is_booking_charged` to understand if we're making money or not out of it.

This PR should provide the necessary fields to start computing Revenue for New Dash.
HOWEVER:
1) I still need to handle Guest Payments computation for Waiver/Deposit services. I'll do it in a separated PR.
2) while doing this exercise I noticed that the current data is not good / consistent with what I was expecting in terms of New Pricing documentation. I will check with Dash Squad so it's correctly filled, before reporting fake numbers...

# 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: #20809
This commit is contained in:
Oriol Roqué Paniagua 2024-11-22 13:50:30 +00:00
parent 2ede94370b
commit 059c92b345
6 changed files with 194 additions and 76 deletions

View file

@ -8,10 +8,36 @@ with
int_core__product_service_to_price as (
select * from {{ ref("int_core__product_service_to_price") }}
),
int_core__product_service_billing_item as (
select * from {{ ref("int_core__product_service_billing_item") }}
),
int_core__protection_plan_to_price as (
select * from {{ ref("int_core__protection_plan_to_price") }}
),
int_core__protection_plan_billing_item as (
select * from {{ ref("int_core__protection_plan_billing_item") }}
),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}),
product_service_billing_aggregation as (
select
id_booking,
id_product_service,
sum(amount_in_gbp) as service_total_price_in_gbp,
min(chargeable_date_utc) as first_chargeable_date_utc,
max(chargeable_date_utc) as last_chargeable_date_utc
from int_core__product_service_billing_item
group by 1, 2
),
protection_plan_billing_aggregation as (
select
id_booking,
id_protection_plan,
sum(amount_in_gbp) as service_total_price_in_gbp,
min(chargeable_date_utc) as first_chargeable_date_utc,
max(chargeable_date_utc) as last_chargeable_date_utc
from int_core__protection_plan_billing_item
group by 1, 2
),
applied_product_services as (
select
bts.id_booking,
@ -33,6 +59,9 @@ with
pstp.invoicing_trigger,
pstp.currency_code,
pstp.amount_local_curr as service_unit_price_local_curr,
psba.service_total_price_in_gbp,
psba.first_chargeable_date_utc,
psba.last_chargeable_date_utc,
bts.is_missing_host_currency_code as is_missing_currency_code,
bts.is_booking_cancelled,
(not pstp.is_default_service) as is_upgraded_service
@ -44,6 +73,10 @@ with
int_core__product_service_to_price pstp
on bts.id_product_service = pstp.id_product_service
and bts.host_currency_code = pstp.currency_code
left join
product_service_billing_aggregation psba
on bts.id_booking = psba.id_booking
and bts.id_product_service = psba.id_product_service
where bts.id_product_service is not null
),
applied_protection_services as (
@ -67,6 +100,9 @@ with
pptp.invoicing_trigger,
pptp.currency_code,
pptp.amount_local_curr as service_unit_price_local_curr,
ppba.service_total_price_in_gbp,
ppba.first_chargeable_date_utc,
ppba.last_chargeable_date_utc,
bts.is_missing_host_currency_code as is_missing_currency_code,
bts.is_booking_cancelled,
(not pptp.is_default_service) as is_upgraded_service
@ -78,6 +114,10 @@ with
int_core__protection_plan_to_price pptp
on bts.id_protection_plan = pptp.id_protection_plan
and bts.host_currency_code = pptp.currency_code
left join
protection_plan_billing_aggregation ppba
on bts.id_booking = ppba.id_booking
and bts.id_protection_plan = ppba.id_protection_plan
where bts.id_protection_plan is not null
),
applied_other_services as (
@ -101,6 +141,9 @@ with
'UNKNOWN' as invoicing_trigger,
'UNKNOWN' as currency_code,
cast(null as decimal) as service_unit_price_local_curr,
cast(null as decimal) as service_total_price_in_gbp,
cast(null as date) as first_chargeable_date_utc,
cast(null as date) as last_chargeable_date_utc,
bts.is_missing_host_currency_code as is_missing_currency_code,
bts.is_booking_cancelled,
-- This case shouldn't occur, but the current missing
@ -119,36 +162,6 @@ with
union all
select *
from applied_other_services
),
local_currency_total_price_computation as (
select
id_booking,
id_booking_service_detail,
service_detail_created_at_utc,
service_detail_updated_at_utc,
booking_created_at_utc,
booking_updated_at_utc,
booking_check_in_at_utc,
booking_check_out_at_utc,
service_business_scope,
service_business_type,
service_source,
service_status,
booking_status,
service_name,
payment_type,
price_base_unit,
invoicing_trigger,
currency_code,
service_unit_price_local_curr,
-- The following is a placeholder for once we have a proper source of truth
cast(null as decimal) as service_total_price_local_curr,
-- The following is a placeholder for once we have a proper source of truth
cast(null as date) as service_charge_date_utc,
is_missing_currency_code,
is_booking_cancelled,
coalesce(is_upgraded_service, false) as is_upgraded_service
from service_aggregation
)
select
id_booking,
@ -170,19 +183,36 @@ select
invoicing_trigger,
currency_code,
service_unit_price_local_curr,
service_unit_price_local_curr * rate as service_unit_price_in_gbp,
service_total_price_local_curr,
service_total_price_local_curr * rate as service_total_price_in_gbp,
service_charge_date_utc,
service_unit_price_local_curr * er.rate as service_unit_price_in_gbp,
service_total_price_in_gbp,
first_chargeable_date_utc as service_first_charge_date_utc,
last_chargeable_date_utc as service_last_charge_date_utc,
is_missing_currency_code,
is_booking_cancelled,
case
when service_total_price_local_curr > 0 then true else false
when service_unit_price_local_curr > 0 then true else false
end as is_paid_service,
is_upgraded_service
from local_currency_total_price_computation bsd
coalesce(is_upgraded_service, false) as is_upgraded_service,
case
when first_chargeable_date_utc is null or last_chargeable_date_utc is null
then true
else false
end as is_missing_charge_date,
case
when first_chargeable_date_utc is null or last_chargeable_date_utc is null
then null
when first_chargeable_date_utc = last_chargeable_date_utc
then true
else false
end as is_service_charged_in_a_single_date
from service_aggregation bsd
left join
int_simple_exchange_rates er
on bsd.service_charge_date_utc = er.rate_date_utc
-- The following line is arbitrary, used to compute the equivalent
-- of the service unit price in gbp at a specific moment in time.
-- If a charge date is available, it will use the last one. If not,
-- it will use the time in which this service was created.
on coalesce(bsd.last_chargeable_date_utc, date(bsd.service_detail_created_at_utc))
= er.rate_date_utc
and bsd.currency_code = er.from_currency
and er.to_currency = 'GBP'

View file

@ -23,8 +23,8 @@ select
bts.new_dash_version,
bts.user_in_new_dash_since_timestamp_at_utc,
sum(bsd.service_total_price_in_gbp) as booking_total_price_in_gbp,
min(bsd.service_charge_date_utc) as first_service_charge_date_utc,
max(bsd.service_charge_date_utc) as last_service_charge_date_utc,
min(bsd.service_first_charge_date_utc) as first_service_charge_date_utc,
max(bsd.service_last_charge_date_utc) as last_service_charge_date_utc,
min(bsd.service_detail_created_at_utc) as first_service_detail_created_at_utc,
max(bsd.service_detail_created_at_utc) as last_service_detail_created_at_utc,
max(bsd.service_detail_updated_at_utc) as last_service_detail_updated_at_utc,
@ -39,6 +39,13 @@ select
when bsd.is_upgraded_service then bsd.id_booking_service_detail else null
end
) as number_of_applied_upgraded_services,
case
when
sum(bsd.service_total_price_in_gbp) > 0
and min(bsd.service_first_charge_date_utc) is not null
then true
else false
end as is_booking_charged,
case
when sum(case when bsd.is_missing_currency_code then 1 else 0 end) > 0
then true
@ -83,7 +90,7 @@ select
then true
else false
end as has_protection_service_business_type,
case when bts.id_deal is null then true else false end as is_missing_id_deal,
bts.is_missing_id_deal,
case
when bts.host_currency_code is null then true else false
end as is_missing_host_currency_code
@ -103,6 +110,7 @@ group by
bts.booking_check_in_at_utc,
bts.booking_check_out_at_utc,
bts.host_currency_code,
bts.is_missing_id_deal,
bts.is_user_in_new_dash,
bts.new_dash_version,
bts.user_in_new_dash_since_timestamp_at_utc

View file

@ -28,6 +28,7 @@ select
b.check_in_at_utc as booking_check_in_at_utc,
b.check_out_at_utc as booking_check_out_at_utc,
uh.account_currency_iso4217 as host_currency_code,
uh.is_missing_id_deal,
uh.is_user_in_new_dash,
uh.new_dash_version,
uh.user_in_new_dash_since_timestamp_at_utc,

View file

@ -6,7 +6,8 @@ with
stg_core__booking_state as (select * from {{ ref("stg_core__booking_state") }}),
int_core__product_service_to_price as (
select * from {{ ref("int_core__product_service_to_price") }}
)
),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }})
select
psbi.id_product_service_billing_item,
psbi.id_booking,
@ -17,6 +18,7 @@ select
upper(bs.booking_state) as booking_status,
pstp.currency_code,
psbi.amount_local_curr,
psbi.amount_local_curr * er.rate as amount_in_gbp,
psbi.chargeable_at_utc,
psbi.chargeable_date_utc,
psbi.created_at_utc,
@ -28,3 +30,8 @@ left join stg_core__booking_state bs on psbi.id_booking_state = bs.id_booking_st
left join
int_core__product_service_to_price pstp
on psbi.id_product_service_to_price = pstp.id_product_service_to_price
left join
int_simple_exchange_rates er
on psbi.chargeable_date_utc = er.rate_date_utc
and pstp.currency_code = er.from_currency
and er.to_currency = 'GBP'

View file

@ -6,25 +6,32 @@ with
stg_core__booking_state as (select * from {{ ref("stg_core__booking_state") }}),
int_core__protection_plan_to_price as (
select * from {{ ref("int_core__protection_plan_to_price") }}
)
),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }})
select
psbi.id_protection_plan_billing_item,
psbi.id_booking,
psbi.id_protection_plan_to_price,
pstp.id_protection_plan,
pstp.protection_display_name as service_name,
upper(pstp.protection_plan_price_name) as service_price_name,
ppbi.id_protection_plan_billing_item,
ppbi.id_booking,
ppbi.id_protection_plan_to_price,
pptp.id_protection_plan,
pptp.protection_display_name as service_name,
upper(pptp.protection_plan_price_name) as service_price_name,
upper(bs.booking_state) as booking_status,
pstp.currency_code,
psbi.amount_local_curr,
psbi.chargeable_at_utc,
psbi.chargeable_date_utc,
psbi.created_at_utc,
psbi.created_date_utc,
psbi.updated_at_utc,
psbi.updated_date_utc
from stg_core__protection_plan_billing_item psbi
left join stg_core__booking_state bs on psbi.id_booking_state = bs.id_booking_state
pptp.currency_code,
ppbi.amount_local_curr,
ppbi.amount_local_curr * er.rate as amount_in_gbp,
ppbi.chargeable_at_utc,
ppbi.chargeable_date_utc,
ppbi.created_at_utc,
ppbi.created_date_utc,
ppbi.updated_at_utc,
ppbi.updated_date_utc
from stg_core__protection_plan_billing_item ppbi
left join stg_core__booking_state bs on ppbi.id_booking_state = bs.id_booking_state
left join
int_core__protection_plan_to_price pstp
on psbi.id_protection_plan_to_price = pstp.id_protection_plan_to_price
int_core__protection_plan_to_price pptp
on ppbi.id_protection_plan_to_price = pptp.id_protection_plan_to_price
left join
int_simple_exchange_rates er
on ppbi.chargeable_date_utc = er.rate_date_utc
and pptp.currency_code = er.from_currency
and er.to_currency = 'GBP'

View file

@ -3336,6 +3336,12 @@ models:
Iso 4217 currency code for the account of the Host.
It can be null.
- name: is_missing_id_deal
data_type: boolean
description: |
Flag to identify if the Host for this booking is missing
the Id Deal or not.
- name: is_user_in_new_dash
data_type: boolean
description: |
@ -3564,16 +3570,13 @@ models:
- name: service_unit_price_in_gbp
data_type: decimal
description: |
Identifies the service unit price converted to GBP with the rate
of the date of charge. Can be null. Can vary over time until the
charge date due to the currency rate estimation in the future.
- name: service_total_price_local_curr
data_type: decimal
description: |
Identifies the current total price of that service in a given
booking in the local currency. Can be null. Can vary over time
depending on the service status, payments, etc.
This is an informative field, use at your own risk.
Identifies the service unit price converted to GBP. If the date of
the charge exists, it will use the latest charge date for the exchange
rate computation. If not, it will use the moment this service detail line
was created. It can be null. It can vary over time due to the currency rate
estimation in the future for charge dates, and can vary also because of
changes in the date used.
- name: service_total_price_in_gbp
data_type: decimal
@ -3584,15 +3587,27 @@ models:
time until the charge date due to the currency rate estimation in
the future.
- name: service_charge_date_utc
- name: service_first_charge_date_utc
data_type: date
description: |
Identifies the moment in time in which the service is charged.
Identifies the first date in which the billing item for this service
is supposed to be charged. It can be null if no billing item is
available. If there's only one billing item, this field will contain
the same value as service_last_charge_date_utc.
- name: service_last_charge_date_utc
data_type: date
description: |
Identifies the last date in which the billing item for this service
is supposed to be charged. It can be null if no billing item is
available. If there's only one billing item, this field will contain
the same value as service_first_charge_date_utc.
- name: is_missing_currency_code
data_type: boolean
description: |
Flag to identify if the applied service is missing the currency code.
Cannot be null.
tests:
- not_null
@ -3600,14 +3615,15 @@ models:
data_type: boolean
description: |
Flag to identify if the booking has been cancelled or not.
Cannot be null.
tests:
- not_null
- name: is_paid_service
data_type: boolean
description: |
Flag to identify it the service total price is strictly
greater than 0 or not.
Flag to identify it the service unit price is strictly
greater than 0 or not. Cannot be null.
tests:
- not_null
@ -3615,10 +3631,27 @@ models:
data_type: boolean
description: |
Flag to identify if the service is an upgraded version,
meaning, it's not a Basic Screening.
meaning, it's not a Basic Screening. Cannot be null.
tests:
- not_null
- name: is_missing_charge_date
data_type: boolean
description: |
Flag to identify if the service has no charge date.
Cannot be null.
tests:
- not_null
- name: is_service_charged_in_a_single_date
data_type: boolean
description: |
Flag to identify if the service is charged in a single date.
If True, it means that service_first_charge_date_utc contains
the same date as service_last_charge_date_utc. If False, these
fields will contain different dates. It can be null, thus meaning
there's no charge date at all.
- name: int_core__booking_summary
description: |
This model contains enriched information aggregated at Booking level regarding
@ -3806,6 +3839,20 @@ models:
Total number of Services different from Basic Screening
applied to this Booking.
- name: is_booking_charged
data_type: boolean
description: |
Flag to identify it the Booking is charged or not.
In essence, it solves the question: are we getting money out
of this booking, or not?
To be considered as charged, a charge date needs to exist as
well as the total price converted to GBP needs to be strictly
greater than 0. The fact that a booking is not charged does
not necessarily mean that it won't be in the future. It cannot
be null.
tests:
- not_null
- name: is_missing_currency_code_in_service_detail
data_type: boolean
description: |
@ -3933,6 +3980,15 @@ models:
tests:
- not_null
- name: amount_in_gbp
data_type: decimal
description: |
Price of the Billing Item, in GBP. It uses the exchange rate according to
chargeable date. It can be positive or negative, depending on if the
line aims to add or remove a previously created amount.
tests:
- not_null
- name: chargeable_at_utc
data_type: timestamp
description: |
@ -4050,6 +4106,15 @@ models:
tests:
- not_null
- name: amount_in_gbp
data_type: decimal
description: |
Price of the Billing Item, in GBP. It uses the exchange rate according to
chargeable date. It can be positive or negative, depending on if the
line aims to add or remove a previously created amount.
tests:
- not_null
- name: chargeable_at_utc
data_type: timestamp
description: |