tons of work, dear god what a spaghetti
This commit is contained in:
parent
dbd2f44795
commit
5101a2a45e
8 changed files with 152 additions and 5 deletions
|
|
@ -9,6 +9,7 @@ services:
|
||||||
- '5432:5432'
|
- '5432:5432'
|
||||||
volumes:
|
volumes:
|
||||||
- dwh-local:/var/lib/postgresql/data
|
- dwh-local:/var/lib/postgresql/data
|
||||||
|
shm_size: 1g
|
||||||
volumes:
|
volumes:
|
||||||
dwh-local:
|
dwh-local:
|
||||||
driver: local
|
driver: local
|
||||||
43
models/intermediate/int_core__booking_charge_events.sql
Normal file
43
models/intermediate/int_core__booking_charge_events.sql
Normal file
|
|
@ -0,0 +1,43 @@
|
||||||
|
with
|
||||||
|
stg_core__booking as (select * from {{ ref("stg_core__booking") }}),
|
||||||
|
int_core__price_plans as (select * from {{ ref("int_core__price_plans") }}),
|
||||||
|
int_core__verification_requests as (
|
||||||
|
select * from {{ ref("int_core__verification_requests") }}
|
||||||
|
),
|
||||||
|
booking_with_price_plans as (
|
||||||
|
select
|
||||||
|
b.id_booking,
|
||||||
|
pp.id_price_plan,
|
||||||
|
pp.booking_fee,
|
||||||
|
-- There is an obscure edge case where a single booking might be charged
|
||||||
|
-- twice according to our logic. We use this to untie by simply picking
|
||||||
|
-- the oldest charge event.
|
||||||
|
row_number() over (
|
||||||
|
partition by b.id_booking order by pp.id_price_plan
|
||||||
|
) as price_plan_priority_rank,
|
||||||
|
-- The below case will be true when a price plan is relevant for the
|
||||||
|
-- booking.
|
||||||
|
case
|
||||||
|
when pp.price_plan_charged_by_type = 'CheckInDate'
|
||||||
|
then b.check_in_at_utc between pp.start_at_utc and pp.end_at_utc
|
||||||
|
when pp.price_plan_charged_by_type in ('VerificationStartDate', 'All')
|
||||||
|
then
|
||||||
|
coalesce(
|
||||||
|
(
|
||||||
|
vr.verification_start_at_utc
|
||||||
|
between pp.start_at_utc and pp.end_at_utc
|
||||||
|
),
|
||||||
|
false
|
||||||
|
)
|
||||||
|
else false
|
||||||
|
end as booking_belongs_to_price_plan
|
||||||
|
from stg_core__booking b
|
||||||
|
left join
|
||||||
|
int_core__verification_requests vr
|
||||||
|
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
|
||||||
|
)
|
||||||
|
|
||||||
|
select bpp.id_booking, bpp.id_price_plan, bpp.booking_fee
|
||||||
|
from booking_with_price_plans bpp
|
||||||
|
where bpp.booking_belongs_to_price_plan = true and price_plan_priority_rank = 1
|
||||||
|
|
@ -4,8 +4,14 @@ with
|
||||||
int_core__duplicate_bookings as (
|
int_core__duplicate_bookings as (
|
||||||
select id_booking, is_duplicate_booking, is_duplicating_booking_with_id
|
select id_booking, is_duplicate_booking, is_duplicating_booking_with_id
|
||||||
from {{ ref("int_core__duplicate_bookings") }}
|
from {{ ref("int_core__duplicate_bookings") }}
|
||||||
|
),
|
||||||
|
int_core__price_plans as (select * from {{ ref("int_core__price_plans") }}),
|
||||||
|
int_core__verification_requests as (
|
||||||
|
select * from {{ ref("int_core__verification_requests") }}
|
||||||
|
),
|
||||||
|
int_core__booking_charge_events as (
|
||||||
|
select * from {{ ref("int_core__booking_charge_events") }}
|
||||||
)
|
)
|
||||||
|
|
||||||
select
|
select
|
||||||
b.id_booking,
|
b.id_booking,
|
||||||
b.id_user_guest,
|
b.id_user_guest,
|
||||||
|
|
@ -36,4 +42,5 @@ select
|
||||||
b.dwh_extracted_at_utc
|
b.dwh_extracted_at_utc
|
||||||
from stg_core__booking b
|
from stg_core__booking b
|
||||||
left join stg_core__booking_state bs on b.id_booking_state = bs.id_booking_state
|
left join stg_core__booking_state bs on b.id_booking_state = bs.id_booking_state
|
||||||
left join int_core__duplicate_bookings as db on b.id_booking = db.id_booking
|
left join int_core__duplicate_bookings db on b.id_booking = db.id_booking
|
||||||
|
left join int_core__booking_charge_events bce on b.id_booking = bce.id_booking
|
||||||
|
|
|
||||||
44
models/intermediate/int_core__price_plans.sql
Normal file
44
models/intermediate/int_core__price_plans.sql
Normal file
|
|
@ -0,0 +1,44 @@
|
||||||
|
with
|
||||||
|
stg_core__price_plan_to_user as (
|
||||||
|
select * from {{ ref("stg_core__price_plan_to_user") }}
|
||||||
|
),
|
||||||
|
stg_core__price_plan_charged_by_type as (
|
||||||
|
select * from {{ ref("stg_core__price_plan_charged_by_type") }}
|
||||||
|
),
|
||||||
|
latest_price_plan_id_by_host as (
|
||||||
|
select id_user_host, max(id_price_plan) as latest_id_price_plan
|
||||||
|
from {{ ref("stg_core__price_plan_to_user") }}
|
||||||
|
group by id_user_host
|
||||||
|
)
|
||||||
|
|
||||||
|
select
|
||||||
|
pp.id_price_plan,
|
||||||
|
pp.id_user_host,
|
||||||
|
ppt.price_plan_charged_by_type,
|
||||||
|
pp.start_at_utc,
|
||||||
|
pp.start_date_utc,
|
||||||
|
coalesce(pp.end_at_utc, '2099-12-31 23:59:59') as end_at_utc,
|
||||||
|
cast(coalesce(pp.end_at_utc, '2099-12-31 23:59:59') as date) end_date_utc,
|
||||||
|
-- active plans have null as an end date, which is very elegant, but a PITA for
|
||||||
|
-- joining. Hence, we just put a date superlong in the future. If you are in
|
||||||
|
-- 2098... hi, make sure to push this :)
|
||||||
|
case
|
||||||
|
when pp.id_price_plan = lpp.latest_id_price_plan then true else false
|
||||||
|
end as is_latest_price_plan_for_host,
|
||||||
|
pp.booking_fee,
|
||||||
|
pp.listing_fee,
|
||||||
|
pp.support_fee,
|
||||||
|
pp.tax_percentage,
|
||||||
|
pp.minimum_billable_listings,
|
||||||
|
pp.minimum_monthly_listing_fee,
|
||||||
|
pp.created_at_utc,
|
||||||
|
pp.created_date_utc,
|
||||||
|
pp.updated_at_utc,
|
||||||
|
pp.updated_date_utc,
|
||||||
|
pp.dwh_extracted_at_utc
|
||||||
|
from stg_core__price_plan_to_user pp
|
||||||
|
left join
|
||||||
|
stg_core__price_plan_charged_by_type ppt
|
||||||
|
on pp.id_price_plan_charged_by_type = ppt.id_price_plan_charged_by_type
|
||||||
|
left join
|
||||||
|
latest_price_plan_id_by_host lpp on lpp.latest_id_price_plan = pp.id_price_plan
|
||||||
|
|
@ -10,7 +10,8 @@ select
|
||||||
title,
|
title,
|
||||||
id_deal,
|
id_deal,
|
||||||
is_deleted,
|
is_deleted,
|
||||||
join_date_utc,
|
joined_at_utc,
|
||||||
|
joined_date_utc,
|
||||||
user_name,
|
user_name,
|
||||||
code_prefix,
|
code_prefix,
|
||||||
billing_town,
|
billing_town,
|
||||||
|
|
@ -27,6 +28,7 @@ select
|
||||||
airbnb_url,
|
airbnb_url,
|
||||||
created_date_utc,
|
created_date_utc,
|
||||||
updated_date_utc,
|
updated_date_utc,
|
||||||
|
verified_at_utc,
|
||||||
verified_date_utc,
|
verified_date_utc,
|
||||||
flag_as_problem,
|
flag_as_problem,
|
||||||
number_of_properties,
|
number_of_properties,
|
||||||
|
|
|
||||||
48
models/intermediate/int_core__verification_requests.sql
Normal file
48
models/intermediate/int_core__verification_requests.sql
Normal file
|
|
@ -0,0 +1,48 @@
|
||||||
|
with
|
||||||
|
stg_core__verification_request as (
|
||||||
|
select * from {{ ref("stg_core__verification_request") }}
|
||||||
|
),
|
||||||
|
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }})
|
||||||
|
select
|
||||||
|
vr.id_verification_request,
|
||||||
|
vr.uuid_verification_request,
|
||||||
|
vr.id_verification_set,
|
||||||
|
vr.id_superhog_verified_set,
|
||||||
|
vr.id_payment_validation_set,
|
||||||
|
vr.id_user_guest,
|
||||||
|
vr.id_user_host,
|
||||||
|
vr.verification_url,
|
||||||
|
vr.callback_url,
|
||||||
|
vr.redirect_url,
|
||||||
|
vr.logo,
|
||||||
|
vr.guest_email,
|
||||||
|
vr.last_name,
|
||||||
|
vr.first_name,
|
||||||
|
vr.guest_phone_number,
|
||||||
|
vr.telephone_code,
|
||||||
|
vr.guest_phone_number_2,
|
||||||
|
guest.joined_at_utc as verification_start_at_utc,
|
||||||
|
guest.joined_date_utc as verification_start_date_utc,
|
||||||
|
guest.verified_at_utc as verification_end_at_utc,
|
||||||
|
guest.verified_date_utc as verification_end_date_utc,
|
||||||
|
vr.link_used_at_utc,
|
||||||
|
vr.link_used_date_utc,
|
||||||
|
vr.expire_at_utc,
|
||||||
|
vr.expire_date_utc,
|
||||||
|
vr.is_deleted,
|
||||||
|
vr.redirect_name,
|
||||||
|
vr.id_one_step_link,
|
||||||
|
vr.success_message,
|
||||||
|
vr.summary,
|
||||||
|
vr.rejection_reason,
|
||||||
|
vr.has_switched_to_mobile,
|
||||||
|
vr.is_verifier_rejected,
|
||||||
|
vr.config,
|
||||||
|
vr.metadata,
|
||||||
|
vr.created_at_utc,
|
||||||
|
vr.created_date_utc,
|
||||||
|
vr.updated_at_utc,
|
||||||
|
vr.updated_date_utc,
|
||||||
|
vr.dwh_extracted_at_utc
|
||||||
|
from stg_core__verification_request vr
|
||||||
|
left join int_core__unified_user guest on vr.id_user_guest = guest.id_user
|
||||||
|
|
@ -7,7 +7,8 @@ with
|
||||||
{{ adapter.quote("AirbnbUrl") }} as airbnb_url,
|
{{ adapter.quote("AirbnbUrl") }} as airbnb_url,
|
||||||
{{ adapter.quote("CreatedDate") }} as created_date_utc,
|
{{ adapter.quote("CreatedDate") }} as created_date_utc,
|
||||||
{{ adapter.quote("UpdatedDate") }} as updated_date_utc,
|
{{ adapter.quote("UpdatedDate") }} as updated_date_utc,
|
||||||
{{ adapter.quote("VerifiedDate") }} as verified_date_utc,
|
{{ adapter.quote("VerifiedDate") }} as verified_at_utc,
|
||||||
|
cast({{ adapter.quote("VerifiedDate") }} as date) as verified_date_utc,
|
||||||
{{ adapter.quote("FlagAsProblem") }} as flag_as_problem,
|
{{ adapter.quote("FlagAsProblem") }} as flag_as_problem,
|
||||||
{{ adapter.quote("SuperhogUserId") }} as id_superhoguser,
|
{{ adapter.quote("SuperhogUserId") }} as id_superhoguser,
|
||||||
{{ adapter.quote("NumberOfProperties") }} as number_of_properties,
|
{{ adapter.quote("NumberOfProperties") }} as number_of_properties,
|
||||||
|
|
|
||||||
|
|
@ -8,7 +8,8 @@ with
|
||||||
{{ adapter.quote("Title") }} as title,
|
{{ adapter.quote("Title") }} as title,
|
||||||
{{ adapter.quote("DealId") }} as id_deal,
|
{{ adapter.quote("DealId") }} as id_deal,
|
||||||
{{ adapter.quote("Deleted") }} as is_deleted,
|
{{ adapter.quote("Deleted") }} as is_deleted,
|
||||||
{{ adapter.quote("JoinDate") }} as join_date_utc,
|
{{ adapter.quote("JoinDate") }} as joined_at_utc,
|
||||||
|
cast({{ adapter.quote("JoinDate") }} as date) as joined_date_utc,
|
||||||
{{ adapter.quote("LastName") }} as last_name,
|
{{ adapter.quote("LastName") }} as last_name,
|
||||||
{{ adapter.quote("UserName") }} as user_name,
|
{{ adapter.quote("UserName") }} as user_name,
|
||||||
{{ adapter.quote("FirstName") }} as first_name,
|
{{ adapter.quote("FirstName") }} as first_name,
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue