docs and moving stuff

This commit is contained in:
Pablo Martin 2024-04-08 09:44:32 +02:00
parent df61682d90
commit 67991800ef
11 changed files with 164 additions and 48 deletions

View file

@ -0,0 +1,58 @@
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_relevant_price_plans as (
select
*,
case
when pp.price_plan_charged_by_type = 'CheckInDate'
then b.check_in_at_utc
when pp.price_plan_charged_by_type in ('VerificationStartDate', 'All')
then vr.verification_start_at_utc
end as booking_fee_charge_at_utc
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
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
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
= true
),
untied_bookings as (
-- If a booking has two valid price plans, take the earliest
select id_booking, min(id_price_plan) as id_price_plan
from booking_with_relevant_price_plans brpp
group by id_booking
)
select
ub.id_booking,
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

View file

@ -0,0 +1,49 @@
with
stg_core__booking as (select * from {{ ref("stg_core__booking") }}),
stg_core__booking_state as (select * from {{ ref("stg_core__booking_state") }}),
int_core__duplicate_bookings as (
select id_booking, is_duplicate_booking, is_duplicating_booking_with_id
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
b.id_booking,
b.id_user_guest,
b.id_user_host,
b.id_integration,
b.id_accommodation,
b.id_booking_source,
b.id_verification_request,
b.id_staging_host_booking,
db.is_duplicate_booking,
db.is_duplicating_booking_with_id,
bs.booking_state,
b.check_in_at_utc,
b.check_in_date_utc,
b.check_out_at_utc,
b.check_out_date_utc,
bce.booking_fee_local,
booking_fee_charge_at_utc,
booking_fee_charge_date_utc,
b.summary,
b.guest_email,
b.guest_last_name,
b.guest_first_name,
b.guest_telephone,
b.additional_guests,
b.unsubscribe_verification_reminder,
b.created_at_utc,
b.created_date_utc,
b.updated_at_utc,
b.updated_date_utc,
b.dwh_extracted_at_utc
from stg_core__booking b
left join stg_core__booking_state bs on b.id_booking_state = bs.id_booking_state
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

View file

@ -0,0 +1,4 @@
with int_core__unified_user as (select * from {{ ref("int_core__unified_user") }})
select id_deal, count(1) as users_with_this_id_deal
from int_core__unified_user
group by id_deal

View file

@ -0,0 +1,32 @@
with
stg_core__booking_state as (select * from {{ ref("stg_core__booking_state") }}),
stg_core__booking_with_dup_flag as (
select
case -- This ugly thing below is true if the booking is duplicate, false if not
when
row_number() over (
partition by id_user_guest, id_accommodation, check_in_date_utc
order by id_booking asc
)
> 1
then true
else false
end as is_duplicate_booking,
*
from {{ ref("stg_core__booking") }}
)
select
db.id_booking,
db.is_duplicate_booking,
b.id_booking as is_duplicating_booking_with_id
from stg_core__booking_with_dup_flag db
left join stg_core__booking_state bs on db.id_booking_state = bs.id_booking_state
left join
stg_core__booking_with_dup_flag b
on (
b.id_user_guest = db.id_user_guest
and b.id_accommodation = db.id_accommodation
and b.check_in_date_utc = db.check_in_date_utc
and b.id_booking != db.id_booking
)
where b.is_duplicate_booking = false and db.is_duplicate_booking = true

View 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_local,
pp.listing_fee_local,
pp.support_fee_local,
pp.tax_percentage,
pp.minimum_billable_listings,
pp.minimum_monthly_listing_fee_local,
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

View file

@ -0,0 +1,40 @@
with
stg_core__user as (select * from {{ ref("stg_core__user") }}),
stg_core__superhog_user as (select * from {{ ref("stg_core__superhog_user") }})
select
id_user,
user_code,
first_name,
last_name,
email,
title,
id_deal,
is_deleted,
joined_at_utc,
joined_date_utc,
user_name,
code_prefix,
billing_town,
company_name,
is_email_confirmed,
is_lockout_enabled,
billing_postcode,
id_billing_country,
is_twofactor_enabled,
access_failed_count,
lockout_end_date_utc,
avatar,
id_airbnb,
airbnb_url,
created_date_utc,
updated_date_utc,
verified_at_utc,
verified_date_utc,
flag_as_problem,
number_of_properties,
id_superhog_verified_set,
platform_comms_recipient,
other_sharing_platform_url,
id_user_verification_status
from stg_core__user as u
inner join stg_core__superhog_user as su on u.id_user = su.id_superhoguser

View file

@ -0,0 +1,47 @@
with
stg_core__verification_to_payment as (
select * from {{ ref("stg_core__verification_to_payment") }}
),
stg_core__verification_payment_type as (
select * from {{ ref("stg_core__verification_payment_type") }}
),
stg_core__payment as (select * from {{ ref("stg_core__payment") }}),
stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}),
int_hardcoded_historical_currency_rates as (
select * from {{ ref("int_hardcoded_historical_currency_rates") }}
)
select
vtp.id_verification_to_payment,
vtp.id_payment,
vtp.is_refundable,
vtp.created_at_utc,
vtp.updated_at_utc,
vtp.payment_due_at_utc,
vtp.payment_due_date_utc,
p.paid_at_utc as payment_paid_at_utc,
p.paid_date_utc as payment_paid_date_utc,
p.payment_reference,
vtp.refund_due_at_utc,
vtp.refund_due_date_utc,
p.refunded_at_utc as payment_refunded_at_utc,
p.refunded_date_utc as payment_refunded_date_utc,
p.refund_payment_reference,
vtp.id_guest_user,
vtp.id_verification,
vpt.verification_payment_type,
p.amount as amount_in_txn_currency,
p.currency,
(p.amount * r.rate) as amount_in_gbp,
ps.payment_status,
p.notes
from stg_core__verification_to_payment vtp
left join stg_core__payment p on vtp.id_payment = p.id_payment
left join
stg_core__verification_payment_type vpt
on vtp.id_verification_payment_type = vpt.id_verification_payment_type
left join stg_core__payment_status ps on p.id_payment_status = ps.id_payment_status
left join
int_hardcoded_historical_currency_rates r
on p.paid_date_utc = r.rate_date
and p.currency = r.from_currency
and r.to_currency = 'GBP'

View 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

View file

@ -0,0 +1,93 @@
version: 2
models:
- name: int_core__duplicate_bookings
description: |
A list of bookings which are considered duplicates of other bookings.
We currently consider two bookings to be duplicate if they have the same:
- Guest user id
- Accomodation id
- Check-in date
Bear in mind these bookings do have different booking ids.
Out of a duplicated tuple of 2 or more bookings:
- Our logic will consider the oldest one to be the "original", not duplicate one.
- This table will contain only the duplicates, and not the original.
columns:
- name: id_booking
data_type: bigint
description: The unique, Superhog generated id for this booking.
- name: is_duplicate_booking
data_type: boolean
description: |
True if the booking is duplicate.
If you are thinking that this is redundant, you are right. All
records in this table will be true. But we keep this field to
make your life easier when joining with other tables.
- name: is_duplicating_booking_with_id
data_type: bigint
description: |
Indicates what's the original booking being duplicated.
If there is a tuple of duplicate bookings {A, B, C}, where A is the
original and the others are the duplicates:
- B and C will appear in this table, A will not.
- The value of this field for both B and C will be A's id.
- name: int_core__booking_charge_events
description: |
Booking charge events is a fancy word for saying: a booking happened,
the related host had a booking fee set up at the right time, hence we
need to charge him.
The table contains one record per booking and shows the associated
booking fee, as well as the point in time in which the charge event was
considered.
Be wary of the booking fees: they don't have an associated currency.
Crazy, I know, but we currently don't store that information in the
backend.
As for the charge dates: the exact point in time at which we consider
that we should be charging a fee depends on billing details of the host
customer. For some bookings, this will be the check-in. For others, its
when the guest begins the verification process.
Not all bookings appear here since we don't charge a fee for all
bookings.
columns:
- name: id_booking
data_type: bigint
description: The unique, Superhog generated id for this booking.
- name: id_price_plan
data_type: bigint
description: The id of the price plan that relates to this booking.
- name: booking_fee_local
data_type: numeric
description: The fee to apply to the booking, in host currency.
- name: booking_fee_charge_at_utc
data_type: timestamp without time zone
description: |
The point in time in which the booking should be invoiced.
This could be the check-in date of the booking or the date in which the guest verification
started, depending on the billing settings of the host.
- name: booking_fee_charge_date_utc
data_type: date
description: |
The date in which the booking should be invoiced.
This could be the check-in date of the booking or the date in which the guest verification
started, depending on the billing settings of the host.