Merged PR 2671: New aggregated model for E-deposit report
# Description New aggregated model for E-deposit report @<Oriol Roqué Paniagua> not sure if this is what you had in mind with categorizing the cases in a variable, if not let me know so maybe we can check it together # Checklist - [x] The edited models and dependants run properly with production data. - [x] The edited models are sufficiently documented. - [x] The edited models contain PK tests, and I've ran and passed them. - [x] I have checked for DRY opportunities with other models and docs. - [x] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #20125
This commit is contained in:
commit
951bc70123
2 changed files with 121 additions and 0 deletions
62
models/intermediate/core/int_edeposit__agg_fee_per_user.sql
Normal file
62
models/intermediate/core/int_edeposit__agg_fee_per_user.sql
Normal 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
|
||||||
|
|
@ -2952,3 +2952,62 @@ models:
|
||||||
- name: created_at_utc
|
- name: created_at_utc
|
||||||
data_type: timestamp without time zone
|
data_type: timestamp without time zone
|
||||||
description: ""
|
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)"
|
||||||
Loading…
Add table
Add a link
Reference in a new issue