edeposit_agg_fee_per_user to reporting

This commit is contained in:
Joaquin Ossa 2024-08-29 11:09:09 +02:00
parent 951bc70123
commit ad2eb2544c
6 changed files with 309 additions and 230 deletions

View file

@ -0,0 +1,62 @@
{% set ok_status = ("Approved", "Flagged") %}
{% set rejected_status = "Rejected" %}
{% set rejected_fee = 0.25 %}
{% set cancellation_fee = 0.25 %}
{% set cancellation_threshold = 0.05 %}
with
int_edeposit__verifications as (
select * from {{ ref("int_edeposit__verifications") }}
),
edeposit_records as (
select
id_booking,
is_cancelled,
channel,
cast(checkin_at_utc as date) as checkin_date_utc,
cast(checkout_at_utc as date) as checkout_date_utc,
creation_at_utc,
verification_status,
id_user_host,
case
when verification_status in {{ ok_status }}
then cast(nightly_fee_local as float) * number_nights
else 0
end as ok_status_fee,
case
when verification_status = '{{ rejected_status }}'
then {{ rejected_fee }}
else 0
end as rejected_fee,
to_char(creation_at_utc, 'YYYY-MM') as year_month_created,
to_char(checkout_at_utc, 'YYYY-MM') as year_month_checkout
from int_edeposit__verifications
where version = 'V2' -- This version V2 indicates records for e-deposit
)
select
year_month_created,
year_month_checkout,
id_user_host,
count(distinct id_booking) as bookings_per_month,
sum(cast(is_cancelled as integer)) as cancelled_per_month,
sum(cast(is_cancelled as integer))::decimal
/ count(distinct id_booking) as cancelled_ratio,
case
when
sum(cast(is_cancelled as integer))::decimal / count(distinct id_booking)
>= {{ cancellation_threshold }}
then sum(cast(is_cancelled as integer)) * {{ cancellation_fee }}
else 0
end as sum_cancelled_fee,
sum(ok_status_fee) as sum_ok_status_fee,
sum(rejected_fee) as sum_rejected_fee,
case
when
sum(cast(is_cancelled as integer))::decimal / count(distinct id_booking)
>= {{ cancellation_threshold }}
then sum(cast(is_cancelled as integer)) * {{ cancellation_fee }}
else 0
end
+ sum(ok_status_fee)
+ sum(rejected_fee) as total_revenue
from edeposit_records
group by year_month_created, year_month_checkout, id_user_host

View file

@ -0,0 +1,47 @@
with
stg_edeposit__verifications as (
select * from {{ ref("stg_edeposit__verifications") }}
)
select
-- note that these ids are not the same as the ones found in Core DWH
-- they are completely unrelated
id as id_verification,
id_booking,
id_user as id_user_host,
id_listing as id_accommodation,
version, -- V1 for Guesty and V2 for E-deposit
case
when version = 'V1' then 'Guesty' when version = 'V2' then 'Edeposit' else null
end as verification_source,
verification_status,
verification_status_reason,
nightly_fee_local,
cast(checkout_at_utc as date) - cast(checkin_at_utc as date) as number_nights,
email_flag,
phone_flag,
watch_list,
channel,
checkin_at_utc,
checkout_at_utc,
is_cancelled,
cancelled_at_utc,
user_email,
guest_email,
guest_last_name,
guest_first_name,
guest_telephone,
company_name,
property_manager_name,
property_manager_email,
listing_name,
listing_town,
listing_country,
listing_postcode,
pets_allowed,
level_of_protection_amount,
level_of_protection_currency,
status_updated_at_utc,
updated_at_utc,
creation_at_utc,
created_at_utc
from stg_edeposit__verifications

View file

@ -0,0 +1,231 @@
version: 2
models:
- name: int_edeposit__verifications
description:
"This table holds records on verifications for e-deposit bookings.
It contains details on validations checked on the guests, guest information
and some booking details like checkin-checkout date or the status of the verification.
The id values found here are completely unrelated to the ones found in Core DWH."
columns:
- name: id_verification
data_type: text
description: "unique Superhog generated id for this verification"
tests:
- unique
- not_null
- name: id_booking
data_type: text
description: "unique Superhog generated id for a booking"
- name: id_user_host
data_type: text
description: "unique Superhog generated id for host"
- name: id_accommodation
data_type: text
description: "unique Superhog generated id for a listing"
- name: version
data_type: text
description:
"value to identify if it is Guesty (V1) or E-deposit (V2)"
tests:
- accepted_values:
values:
- V1
- V2
- name: verification_source
data_type: text
description:
"source of the verification for the booking"
tests:
- accepted_values:
values:
- Guesty
- Edeposit
- name: verification_status
data_type: text
description: "status of the verification"
- name: verification_status_reason
data_type: text
description: "short explanation for status"
- name: nightly_fee_local
data_type: text
description: "fee charged per night"
- name: number_nights
data_type: integer
description: "number of nights for the booking"
- name: email_flag
data_type: text
description: ""
- name: phone_flag
data_type: text
description: ""
- name: watch_list
data_type: text
description: ""
- name: channel
data_type: text
description: ""
- name: checkin_at_utc
data_type: timestamp without time zone
description: "Timestamp of checkin for the booking"
- name: checkout_at_utc
data_type: timestamp without time zone
description: "Timestamp of checkout for the booking"
- name: is_cancelled
data_type: boolean
description: ""
- name: cancelled_at_utc
data_type: timestamp without time zone
description: "Timestamp of cancellation of the booking"
- name: user_email
data_type: text
description: ""
- name: guest_email
data_type: text
description: ""
- name: guest_last_name
data_type: text
description: ""
- name: guest_first_name
data_type: text
description: ""
- name: guest_telephone
data_type: text
description: ""
- name: company_name
data_type: text
description: ""
- name: property_manager_name
data_type: text
description: ""
- name: property_manager_email
data_type: text
description: ""
- name: listing_name
data_type: text
description: ""
- name: listing_town
data_type: text
description: ""
- name: listing_country
data_type: text
description: ""
- name: listing_postcode
data_type: text
description: ""
- name: pets_allowed
data_type: boolean
description: ""
- name: level_of_protection_amount
data_type: integer
description: ""
- name: level_of_protection_currency
data_type: text
description: ""
- name: status_updated_at_utc
data_type: timestamp without time zone
description: "Timestamp when status was last updated"
- name: updated_at_utc
data_type: timestamp without time zone
description: "Timestamp of last updated"
- name: creation_at_utc
data_type: timestamp without time zone
description: ""
- name: created_at_utc
data_type: timestamp without time zone
description: ""
- name: int_edeposit__agg_fee_per_user
description:
"This table holds detailed data on revenue generated through e-deposit verifications.
Each record provides insights into booking activities per user, including the number
of bookings, cancellations, and associated fees within specific months. Each record
captures data for bookings created in a particular month along with their corresponding
checkout month, allowing for a comprehensive view of the booking lifecycle and associated
revenues within those periods."
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- year_month_created
- year_month_checkout
- id_user_host
columns:
- name: year_month_created
data_type: text
description: "first day of month of created date"
- name: year_month_checkout
data_type: text
description: "first day of month of check-out date"
- name: id_user_host
data_type: text
description: "unique id value for user host"
- name: bookings_per_month
data_type: bigint
description: "total number of bookings"
- name: cancelled_per_month
data_type: bigint
description: "number of cancelled bookings"
- name: cancelled_ratio
data_type: numeric
description: "ratio of cancelled bookings over total bookings"
- name: sum_cancelled_fee
data_type: numeric
description: "sum of fees charged for cancelled bookings
(currency-less)"
- name: sum_ok_status_fee
data_type: double precision
description: |
"sum of fees charged for bookings with status 'Approved' or 'Flagged'
(currency-less)"
- name: sum_rejected_fee
data_type: numeric
description: "sum of fees charged for rejected bookings
(currency-less)"
- name: total_revenue
data_type: double precision
description: "total sum of fees charged (currency-less)"