1st commit edeposit_verifications

This commit is contained in:
Joaquin Ossa 2024-08-27 14:55:29 +02:00
parent 2facaceec0
commit 7786f2e770

View file

@ -0,0 +1,70 @@
with
stg_edeposit__verifications as (
select * from {{ ref("stg_edeposit__verifications") }}
),
edeposit_records as (
select
id_booking,
cancelled_at_utc,
is_cancelled,
channel,
cast(checkin_at_utc as date) as checkin_date_utc,
cast(checkout_at_utc as date) as checkout_date_utc,
property_manager_name,
created_at_utc,
creation_at_utc,
id_listing,
listing_country,
listing_town,
cast(checkout_at_utc as date) - cast(checkin_at_utc as date) as nights,
cast(nightly_fee_local as float) as nightly_fee_local,
verification_status,
status_updated_at_utc,
updated_at_utc,
id_user,
id as verification_id,
case
when verification_status = 'Approved' or verification_status = 'Flagged'
then cast(nightly_fee_local as float)
else 0
end as ok_status_night_fee,
case
when verification_status = 'Approved' or verification_status = 'Flagged'
then
cast(nightly_fee_local as float)
* (cast(checkout_at_utc as date) - cast(checkin_at_utc as date))
else 0
end as ok_status_fee,
case
when verification_status = 'Rejected' then 0.25 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,
"version"
from {{ ref("stg_edeposit__verifications") }} -- Use ref() to reference other dbt models
where version = 'V2'
)
select
year_month_created,
year_month_checkout,
id_user,
count(*) as bookings_per_month,
sum(cast(is_cancelled as integer)) as cancelled_per_month,
sum(cast(is_cancelled as integer))::decimal / count(*) as cancelled_ratio,
case
when sum(cast(is_cancelled as integer))::decimal / count(*) >= 0.05
then sum(cast(is_cancelled as integer)) * 0.25
else 0
end as sum_cancelled_fee,
sum(ok_status_fee) as ok_status_fee_sum,
sum(rejected_fee) as rejected_fee_sum,
case
when sum(cast(is_cancelled as integer))::decimal / count(*) >= 0.05
then sum(cast(is_cancelled as integer)) * 0.25
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
order by year_month_created