Merged PR 2679: edeposit_agg_fee_per_user to reporting

# Description

edeposit fees per verification
I modified the model so it contains only the fees charged per verification so then we can do the grouping and filters in power bi depending on how it needs to be displayed.
# 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:
Joaquin Ossa 2024-09-04 07:08:38 +00:00
commit 470e5c7990
2 changed files with 193 additions and 1 deletions

View file

@ -0,0 +1,93 @@
{% 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") }}
),
stg_core__edeposit_user as (select * from {{ ref("stg_core__edeposit_user") }}),
int_daily_currency_exchange_rates as (
select * from {{ ref("int_daily_currency_exchange_rates") }}
),
edeposit_records as (
select
v.id_verification,
v.id_user_partner,
v.id_booking,
eu.currency,
cer.rate,
v.is_cancelled,
case
when v.verification_status in {{ ok_status }}
then v.nightly_fee_local * v.number_nights
else 0
end as ok_status_fee_in_txn_currency,
case
when v.verification_status in {{ ok_status }}
then cer.rate * v.nightly_fee_local * v.number_nights
else 0
end as ok_status_fee_in_gbp,
case
when v.verification_status = '{{ rejected_status }}'
then {{ rejected_fee }}
else 0
end as rejected_fee_in_txn_currency,
case
when v.verification_status = '{{ rejected_status }}'
then cer.rate * {{ rejected_fee }}
else 0
end as rejected_fee_in_gbp,
to_char(v.checkout_at_utc, 'YYYY-MM') as year_month_checkout
from int_edeposit__verifications v
inner join stg_core__edeposit_user eu on v.id_user_partner = eu.id_user_partner
left join
int_daily_currency_exchange_rates cer
on cer.from_currency = eu.currency
and cer.rate_date_utc = v.checkout_date_utc
and cer.to_currency = 'GBP'
where version = 'V2'
),
monthly_cancellation_threshold as (
select
id_user_partner,
year_month_checkout,
case
when
sum(cast(is_cancelled as integer))::decimal / count(id_booking)
>= {{ cancellation_threshold }}
then true
else false
end as is_cancellation_threshold_surpassed
from edeposit_records
group by id_user_partner, year_month_checkout
)
select
v.id_verification,
v.id_booking,
er.currency,
er.ok_status_fee_in_txn_currency,
er.ok_status_fee_in_gbp,
er.rejected_fee_in_txn_currency,
er.rejected_fee_in_gbp,
case
when ct.is_cancellation_threshold_surpassed is true
then {{ cancellation_fee }}
else 0
end as cancelled_fee_in_txn_currency,
case
when ct.is_cancellation_threshold_surpassed is true
then rate * {{ cancellation_fee }}
else 0
end as cancelled_fee_in_gbp,
v.created_date_utc,
v.checkout_date_utc
from int_edeposit__verifications v
inner join edeposit_records er on er.id_verification = v.id_verification
inner join
monthly_cancellation_threshold ct
on (
er.id_user_partner = ct.id_user_partner
and er.year_month_checkout = ct.year_month_checkout
)

View file

@ -21,7 +21,10 @@ models:
- name: id_booking - name: id_booking
data_type: text data_type: text
description: "unique Superhog generated id for a booking" description:
"unique Superhog generated id for a booking.
note that this could be duplicated and both will be charged,
it's up to the user to no generate duplicate verifications"
- name: id_user_partner - name: id_user_partner
data_type: text data_type: text
@ -206,3 +209,99 @@ models:
- name: created_date_utc - name: created_date_utc
data_type: date data_type: date
description: "Date of creation of the verification in the system" description: "Date of creation of the verification in the system"
- name: int_edeposit__verification_fees
description:
"This table shows all fee charges per verification for E-deposit.
Cancellation fee is charged when the monthly rate of cancelled bookings over
total booking of the partner surpasses the threshold (currently set at 0.05).
Both cancellation and rejection fees are set to 0.25 though it might change.
Fees are both in the currency used by the user and in GBP"
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.
note that this could be duplicated and both will be charged,
it's up to the user to no generate duplicate verifications"
tests:
- not_null
- name: currency
data_type: text
description: "currency in which the transaction actually happened"
tests:
- not_null
- name: ok_status_fee_in_txn_currency
data_type: numeric
description: "fee charged in used currency for approved or flagged verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: ok_status_fee_in_gbp
data_type: numeric
description: "fee charged in gbp for approved or flagged verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: rejected_fee_in_txn_currency
data_type: numeric
description: "fee charged in used currency for rejected verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: rejected_fee_in_gbp
data_type: numeric
description: "fee charged in gbp for rejected verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: cancelled_fee_in_txn_currency
data_type: numeric
description: "fee charged in used currency for cancelled verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: cancelled_fee_in_gbp
data_type: numeric
description: "fee charged in gbp for cancelled verifications"
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: checkout_date_utc
data_type: date
description: "Date of checkout for the booking"
tests:
- not_null
- name: created_date_utc
data_type: date
description: "Date of creation of the verification in the system"
tests:
- not_null