Merged PR 4423: Logic for Billable Bookings in New Dash Bookings

# Description

Changes:
* Tags services to be billed (invoiced to host) in the staging models of product_service and protection_plan
* Propagates into booking_service_detail master table. This also computes billable dates.
* Propagates into booking_summary master table. This has the final determination of a booking being billable or not, and when the first and last billing should occur.

# 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: #27619
This commit is contained in:
Oriol Roqué Paniagua 2025-02-17 15:01:44 +00:00
parent 399feba9af
commit a3793121af
6 changed files with 160 additions and 6 deletions

View file

@ -111,7 +111,8 @@ with
psba.last_chargeable_date_utc) as last_chargeable_date_utc,
bts.is_missing_host_currency_code as is_missing_currency_code,
bts.is_booking_cancelled,
(not ps.is_default_service) as is_upgraded_service
(not ps.is_default_service) as is_upgraded_service,
ps.is_billable_service
from int_core__booking_to_service bts
inner join
stg_core__product_service ps
@ -157,7 +158,8 @@ with
ppba.last_chargeable_date_utc,
bts.is_missing_host_currency_code as is_missing_currency_code,
bts.is_booking_cancelled,
(not pp.is_default_service) as is_upgraded_service
(not pp.is_default_service) as is_upgraded_service,
pp.is_billable_service
from int_core__booking_to_service bts
inner join
stg_core__protection_plan pp
@ -214,7 +216,8 @@ with
when bts.service_name in {{ waiver_or_deposit_offered_but_not_chosen }}
then true
else false
end as is_upgraded_service
end as is_upgraded_service,
false as is_billable_service
from int_core__booking_to_service bts
where bts.id_protection_plan is null and bts.id_product_service is null
),
@ -253,12 +256,23 @@ select
service_total_price_in_gbp,
first_chargeable_date_utc as service_first_chargeable_date_utc,
last_chargeable_date_utc as service_last_chargeable_date_utc,
case
when coalesce(is_billable_service, false)
then first_chargeable_date_utc
else null
end as service_first_billable_date_utc,
case
when coalesce(is_billable_service, false)
then last_chargeable_date_utc
else null
end as service_last_billable_date_utc,
is_missing_currency_code,
is_booking_cancelled,
case
when service_unit_price_local_curr > 0 then true else false
end as is_paid_service,
coalesce(is_upgraded_service, false) as is_upgraded_service,
coalesce(is_billable_service, false) as is_billable_service,
case
when first_chargeable_date_utc is null or last_chargeable_date_utc is null
then true

View file

@ -33,6 +33,8 @@ select
sum(bsd.service_total_price_in_gbp) as booking_total_price_in_gbp,
min(bsd.service_first_chargeable_date_utc) as service_first_chargeable_date_utc,
max(bsd.service_last_chargeable_date_utc) as service_last_chargeable_date_utc,
min(bsd.service_first_billable_date_utc) as service_first_billable_date_utc,
max(bsd.service_last_billable_date_utc) as service_last_billable_date_utc,
min(bsd.service_detail_created_at_utc) as service_first_created_at_utc,
max(bsd.service_detail_created_at_utc) as service_last_created_at_utc,
max(bsd.service_detail_updated_at_utc) as service_last_updated_at_utc,
@ -47,6 +49,11 @@ select
when bsd.is_upgraded_service then bsd.id_booking_service_detail else null
end
) as number_of_applied_upgraded_services,
count(
distinct case
when bsd.is_billable_service then bsd.id_booking_service_detail else null
end
) as number_of_applied_billable_services,
case
when
sum(bsd.service_total_price_in_gbp) > 0
@ -54,6 +61,20 @@ select
then true
else false
end as is_booking_chargeable,
case
when
sum(
case
when bsd.is_billable_service
then bsd.service_total_price_in_gbp
else 0
end
)
> 0
and min(bsd.service_first_billable_date_utc) is not null
then true
else false
end as is_booking_billable,
case
when sum(case when bsd.is_missing_currency_code then 1 else 0 end) > 0
then true
@ -74,6 +95,11 @@ select
then true
else false
end as has_upgraded_services,
case
when sum(case when bsd.is_billable_service then 1 else 0 end) > 0
then true
else false
end as has_billable_services,
case
when
sum(case when bsd.service_business_type = 'SCREENING' then 1 else 0 end) > 0

View file

@ -3902,17 +3902,39 @@ models:
data_type: date
description: |
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
is supposed to be charged or when the guest payment happens.
It can be null if no service supposed to be charged is available.
If there's only one chargeable service, this field will contain
the same value as service_last_chargeable_date_utc.
- name: service_last_chargeable_date_utc
data_type: date
description: |
Identifies the last date in which the billing item for this service
is supposed to be charged or when the guest payment happens.
It can be null if no service supposed to be charged is available.
If there's only one chargeable service, this field will contain
the same value as service_first_chargeable_date_utc.
- name: service_first_billable_date_utc
data_type: date
description: |
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_first_chargeable_date_utc.
the same value as service_last_billable_date_utc.
It's similar to Chargeable Services logic but it only considers
Billable Services to the Host (excluding Guest Payments and free services).
- name: service_last_billable_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_billable_date_utc.
It's similar to Chargeable Services logic but it only considers
Billable Services to the Host (excluding Guest Payments and free services).
- name: is_missing_currency_code
data_type: boolean
@ -3946,6 +3968,15 @@ models:
data_tests:
- not_null
- name: is_billable_service
data_type: boolean
description: |
Flag that determines if the service is billable or not.
If the service is billable, it is supposed to be included in the
invoice to the host.
data_tests:
- not_null
- name: is_missing_chargeable_date
data_type: boolean
description: |
@ -4170,6 +4201,22 @@ models:
Identifies the last moment in time in which the last
service applied to this booking is supposed to be charged.
- name: service_first_billable_date_utc
data_type: date
description: |
Identifies the first moment in time in which the first
service applied to this booking is supposed to be billed.
This excludes Guest Payments, and only includes services to
be invoiced to the Host.
- name: service_last_billable_date_utc
data_type: date
description: |
Identifies the last moment in time in which the last
service applied to this booking is supposed to be billed.
This excludes Guest Payments, and only includes services to
be invoiced to the Host.
- name: service_first_created_at_utc
data_type: timestamp
description: |
@ -4211,6 +4258,12 @@ models:
Total number of Services different from Basic Screening
applied to this Booking.
- name: number_of_applied_billable_services
data_type: integer
description: |
Total number of Services that require an invoice to the Host
to the Host, that are applied to this Booking.
- name: is_booking_chargeable
data_type: boolean
description: |
@ -4226,6 +4279,25 @@ models:
data_tests:
- not_null
- name: is_booking_billable
data_type: boolean
description: |
Flag to identify it the Booking is billable or not.
In essence, it solves the question: are we supposed to invoice
a certain amount to the host to get money out of this booking, or not?
To be considered as billable, a billable date needs to exist
as well as the total price of billable services, converted to GBP,
need to be strictly greater than 0.
The fact that a booking is not billable does not necessarily mean that
it won't be in the future.
The fact that a booking is not billable does not necessarily mean that
it's not chargeable, since Guest Payments could still apply.
Similarly, if the booking is billable it does not necessarily mean that
is actually billed.
It cannot be null.
data_tests:
- not_null
- name: is_missing_currency_code_in_service_detail
data_type: boolean
description: |
@ -4248,6 +4320,11 @@ models:
Flag to identify if the booking has any service different from
Basic Screening or not.
- name: has_billable_services
data_type: boolean
description: |
Flag to identify if the booking has any billable service or not.
- name: has_screening_service_business_type
data_type: boolean
description: |

View file

@ -576,6 +576,15 @@ models:
data_tests:
- not_null
- name: is_billable_service
data_type: boolean
description: |
Flag that determines if the service is billable or not.
If the service is billable, it is supposed to be included in the
invoice to the host.
data_tests:
- not_null
- name: dwh_extracted_at_utc
data_type: timestamp
description: |
@ -775,6 +784,14 @@ models:
or an upgraded service (False).
data_tests:
- not_null
- name: is_billable_service
data_type: boolean
description: |
Flag that determines if the service is billable or not.
If the service is billable, it is supposed to be included in the
invoice to the host.
data_tests:
- not_null
- name: dwh_extracted_at_utc
data_type: timestamp
description: |

View file

@ -49,5 +49,17 @@ select
then true
else false
end as is_default_service,
case
when
id_product_service not in (
1, -- 'BASIC SCREENING'
5, -- 'BASIC DAMAGE DEPOSIT'
6, -- 'DAMAGE DEPOSIT PLUS'
7, -- 'BASIC WAIVER'
8 -- 'WAIVER PLUS'
)
then true
else false
end as is_billable_service,
dwh_extracted_at_utc
from stg_core__product_service

View file

@ -51,6 +51,14 @@ select
then true
else false
end as is_default_service,
case
when
id_protection_plan not in (
1 -- 'BASIC SCREENING'
)
then true
else false
end as is_billable_service,
pp.dwh_extracted_at_utc
from raw_protection_plan pp
left join raw_protection p on pp.id_protection = p.id