a lot of changes
This commit is contained in:
parent
5101a2a45e
commit
df61682d90
9 changed files with 88 additions and 29 deletions
|
|
@ -4,19 +4,24 @@ with
|
||||||
int_core__verification_requests as (
|
int_core__verification_requests as (
|
||||||
select * from {{ ref("int_core__verification_requests") }}
|
select * from {{ ref("int_core__verification_requests") }}
|
||||||
),
|
),
|
||||||
booking_with_price_plans as (
|
booking_with_relevant_price_plans as (
|
||||||
select
|
select
|
||||||
b.id_booking,
|
*,
|
||||||
pp.id_price_plan,
|
case
|
||||||
pp.booking_fee,
|
when pp.price_plan_charged_by_type = 'CheckInDate'
|
||||||
-- There is an obscure edge case where a single booking might be charged
|
then b.check_in_at_utc
|
||||||
-- twice according to our logic. We use this to untie by simply picking
|
when pp.price_plan_charged_by_type in ('VerificationStartDate', 'All')
|
||||||
-- the oldest charge event.
|
then vr.verification_start_at_utc
|
||||||
row_number() over (
|
end as booking_fee_charge_at_utc
|
||||||
partition by b.id_booking order by pp.id_price_plan
|
from stg_core__booking b
|
||||||
) as price_plan_priority_rank,
|
left join
|
||||||
-- The below case will be true when a price plan is relevant for the
|
int_core__verification_requests vr
|
||||||
-- booking.
|
on b.id_verification_request = vr.id_verification_request
|
||||||
|
left join int_core__price_plans pp on b.id_user_host = pp.id_user_host
|
||||||
|
where
|
||||||
|
-- The dates that defines which price plan applies to the booking depends
|
||||||
|
-- on charged by type. With the below case, we evaluate if a certain price
|
||||||
|
-- plan relates to the booking
|
||||||
case
|
case
|
||||||
when pp.price_plan_charged_by_type = 'CheckInDate'
|
when pp.price_plan_charged_by_type = 'CheckInDate'
|
||||||
then b.check_in_at_utc between pp.start_at_utc and pp.end_at_utc
|
then b.check_in_at_utc between pp.start_at_utc and pp.end_at_utc
|
||||||
|
|
@ -30,14 +35,24 @@ with
|
||||||
false
|
false
|
||||||
)
|
)
|
||||||
else false
|
else false
|
||||||
end as booking_belongs_to_price_plan
|
end
|
||||||
from stg_core__booking b
|
= true
|
||||||
left join
|
),
|
||||||
int_core__verification_requests vr
|
untied_bookings as (
|
||||||
on b.id_verification_request = vr.id_verification_request
|
-- If a booking has two valid price plans, take the earliest
|
||||||
left join int_core__price_plans pp on b.id_user_host = pp.id_user_host
|
select id_booking, min(id_price_plan) as id_price_plan
|
||||||
|
from booking_with_relevant_price_plans brpp
|
||||||
|
group by id_booking
|
||||||
)
|
)
|
||||||
|
|
||||||
select bpp.id_booking, bpp.id_price_plan, bpp.booking_fee
|
select
|
||||||
from booking_with_price_plans bpp
|
ub.id_booking,
|
||||||
where bpp.booking_belongs_to_price_plan = true and price_plan_priority_rank = 1
|
ub.id_price_plan,
|
||||||
|
brpp.booking_fee_local,
|
||||||
|
brpp.booking_fee_charge_at_utc,
|
||||||
|
cast(brpp.booking_fee_charge_at_utc as date) as booking_fee_charge_date_utc
|
||||||
|
from untied_bookings ub
|
||||||
|
left join
|
||||||
|
booking_with_relevant_price_plans brpp
|
||||||
|
on ub.id_booking = brpp.id_booking
|
||||||
|
and ub.id_price_plan = brpp.id_price_plan
|
||||||
|
|
|
||||||
|
|
@ -28,6 +28,9 @@ select
|
||||||
b.check_in_date_utc,
|
b.check_in_date_utc,
|
||||||
b.check_out_at_utc,
|
b.check_out_at_utc,
|
||||||
b.check_out_date_utc,
|
b.check_out_date_utc,
|
||||||
|
bce.booking_fee_local,
|
||||||
|
booking_fee_charge_at_utc,
|
||||||
|
booking_fee_charge_date_utc,
|
||||||
b.summary,
|
b.summary,
|
||||||
b.guest_email,
|
b.guest_email,
|
||||||
b.guest_last_name,
|
b.guest_last_name,
|
||||||
|
|
|
||||||
|
|
@ -25,12 +25,12 @@ select
|
||||||
case
|
case
|
||||||
when pp.id_price_plan = lpp.latest_id_price_plan then true else false
|
when pp.id_price_plan = lpp.latest_id_price_plan then true else false
|
||||||
end as is_latest_price_plan_for_host,
|
end as is_latest_price_plan_for_host,
|
||||||
pp.booking_fee,
|
pp.booking_fee_local,
|
||||||
pp.listing_fee,
|
pp.listing_fee_local,
|
||||||
pp.support_fee,
|
pp.support_fee_local,
|
||||||
pp.tax_percentage,
|
pp.tax_percentage,
|
||||||
pp.minimum_billable_listings,
|
pp.minimum_billable_listings,
|
||||||
pp.minimum_monthly_listing_fee,
|
pp.minimum_monthly_listing_fee_local,
|
||||||
pp.created_at_utc,
|
pp.created_at_utc,
|
||||||
pp.created_date_utc,
|
pp.created_date_utc,
|
||||||
pp.updated_at_utc,
|
pp.updated_at_utc,
|
||||||
|
|
|
||||||
12
models/reporting/core/core__bookings.sql
Normal file
12
models/reporting/core/core__bookings.sql
Normal file
|
|
@ -0,0 +1,12 @@
|
||||||
|
with int_core__bookings as (select * from {{ ref("int_core__bookings") }})
|
||||||
|
|
||||||
|
select
|
||||||
|
b.id_booking,
|
||||||
|
b.id_user_guest,
|
||||||
|
b.id_user_host,
|
||||||
|
b.id_accommodation,
|
||||||
|
b.is_duplicate_booking,
|
||||||
|
b.booking_fee_local,
|
||||||
|
b.booking_fee_charge_at_utc,
|
||||||
|
b.booking_fee_charge_date_utc
|
||||||
|
from int_core__bookings b
|
||||||
|
|
@ -1,3 +1,14 @@
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
indexes=[
|
||||||
|
{"columns": ["id_booking"]},
|
||||||
|
{"columns": ["id_user_host"]},
|
||||||
|
{"columns": ["id_user_guest"]},
|
||||||
|
{"columns": ["id_verification_request"]},
|
||||||
|
]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
with
|
with
|
||||||
raw_booking as (select * from {{ source("core", "Booking") }}),
|
raw_booking as (select * from {{ source("core", "Booking") }}),
|
||||||
stg_core__booking as (
|
stg_core__booking as (
|
||||||
|
|
|
||||||
|
|
@ -1,3 +1,5 @@
|
||||||
|
{{ config(indexes=[{"columns": ["id_price_plan"]}, {"columns": ["id_user_host"]}]) }}
|
||||||
|
|
||||||
with
|
with
|
||||||
raw_price_plan_to_user as (select * from {{ source("core", "PricePlanToUser") }}),
|
raw_price_plan_to_user as (select * from {{ source("core", "PricePlanToUser") }}),
|
||||||
stg_core__price_plan_to_user as (
|
stg_core__price_plan_to_user as (
|
||||||
|
|
@ -10,12 +12,13 @@ with
|
||||||
cast({{ adapter.quote("StartDate") }} as date) as start_date_utc,
|
cast({{ adapter.quote("StartDate") }} as date) as start_date_utc,
|
||||||
{{ adapter.quote("EndDate") }} as end_at_utc,
|
{{ adapter.quote("EndDate") }} as end_at_utc,
|
||||||
cast({{ adapter.quote("EndDate") }} as date) end_date_utc,
|
cast({{ adapter.quote("EndDate") }} as date) end_date_utc,
|
||||||
{{ adapter.quote("BookingFeeNet") }} as booking_fee,
|
{{ adapter.quote("BookingFeeNet") }} as booking_fee_local,
|
||||||
{{ adapter.quote("ListingFeeNet") }} as listing_fee,
|
{{ adapter.quote("ListingFeeNet") }} as listing_fee_local,
|
||||||
{{ adapter.quote("SupportFeeNet") }} as support_fee,
|
{{ adapter.quote("SupportFeeNet") }} as support_fee_local,
|
||||||
{{ adapter.quote("TaxPercentage") }} as tax_percentage,
|
{{ adapter.quote("TaxPercentage") }} as tax_percentage,
|
||||||
{{ adapter.quote("MinBillableListings") }} as minimum_billable_listings,
|
{{ adapter.quote("MinBillableListings") }} as minimum_billable_listings,
|
||||||
{{ adapter.quote("MinMonthlyListingFee") }} as minimum_monthly_listing_fee,
|
{{ adapter.quote("MinMonthlyListingFee") }}
|
||||||
|
as minimum_monthly_listing_fee_local,
|
||||||
{{ adapter.quote("CreatedDate") }} as created_at_utc,
|
{{ adapter.quote("CreatedDate") }} as created_at_utc,
|
||||||
cast({{ adapter.quote("CreatedDate") }} as date) as created_date_utc,
|
cast({{ adapter.quote("CreatedDate") }} as date) as created_date_utc,
|
||||||
{{ adapter.quote("UpdatedDate") }} as updated_at_utc,
|
{{ adapter.quote("UpdatedDate") }} as updated_at_utc,
|
||||||
|
|
|
||||||
|
|
@ -1,3 +1,5 @@
|
||||||
|
{{ config(indexes=[{"columns": ["id_superhoguser"]}]) }}
|
||||||
|
|
||||||
with
|
with
|
||||||
raw_superhog_user as (select * from {{ source("core", "superhog_user") }}),
|
raw_superhog_user as (select * from {{ source("core", "superhog_user") }}),
|
||||||
stg_core__superhog_user as (
|
stg_core__superhog_user as (
|
||||||
|
|
|
||||||
|
|
@ -1,3 +1,5 @@
|
||||||
|
{{ config(indexes=[{"columns": ["id_user"]}]) }}
|
||||||
|
|
||||||
with
|
with
|
||||||
raw_user as (select * from {{ source("core", "User") }}),
|
raw_user as (select * from {{ source("core", "User") }}),
|
||||||
stg_core__user as (
|
stg_core__user as (
|
||||||
|
|
|
||||||
|
|
@ -1,3 +1,14 @@
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
indexes=[
|
||||||
|
{"columns": ["id_verification_request"]},
|
||||||
|
{"columns": ["id_user_guest"]},
|
||||||
|
{"columns": ["id_user_host"]},
|
||||||
|
]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
|
||||||
with
|
with
|
||||||
raw_verification_request as (
|
raw_verification_request as (
|
||||||
select * from {{ source("core", "VerificationRequest") }}
|
select * from {{ source("core", "VerificationRequest") }}
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue