Merged PR 4076: CIH fees
# Description Added booking fees for CIH requests and new model of aggregated monthly fee per user # 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: #26158
This commit is contained in:
commit
6141af1eff
5 changed files with 147 additions and 2 deletions
|
|
@ -4,7 +4,8 @@ with
|
||||||
),
|
),
|
||||||
int_core__check_in_hero_users as (
|
int_core__check_in_hero_users as (
|
||||||
select * from {{ ref("int_core__check_in_hero_users") }}
|
select * from {{ ref("int_core__check_in_hero_users") }}
|
||||||
)
|
),
|
||||||
|
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }})
|
||||||
|
|
||||||
select
|
select
|
||||||
c.id_record,
|
c.id_record,
|
||||||
|
|
@ -12,6 +13,10 @@ select
|
||||||
c.id_reservation,
|
c.id_reservation,
|
||||||
c.id_accommodation,
|
c.id_accommodation,
|
||||||
chu.id_currency,
|
chu.id_currency,
|
||||||
|
chu.currency_code,
|
||||||
|
chu.booking_fee_in_local_currency,
|
||||||
|
ser.rate as exchange_rate_to_gbp,
|
||||||
|
ser.rate * chu.booking_fee_in_local_currency as booking_fee_in_gbp,
|
||||||
c.guest_last_name,
|
c.guest_last_name,
|
||||||
c.guest_first_name,
|
c.guest_first_name,
|
||||||
c.guest_email,
|
c.guest_email,
|
||||||
|
|
@ -39,3 +44,8 @@ select
|
||||||
c.created_date_utc
|
c.created_date_utc
|
||||||
from stg_check_in_hero__checkins c
|
from stg_check_in_hero__checkins c
|
||||||
inner join int_core__check_in_hero_users chu on c.id_user_partner = chu.id_apim_user
|
inner join int_core__check_in_hero_users chu on c.id_user_partner = chu.id_apim_user
|
||||||
|
left join
|
||||||
|
int_simple_exchange_rates ser
|
||||||
|
on chu.currency_code = ser.from_currency
|
||||||
|
and ser.to_currency = 'GBP'
|
||||||
|
and c.created_date_utc = ser.rate_date_utc
|
||||||
|
|
|
||||||
|
|
@ -0,0 +1,18 @@
|
||||||
|
with
|
||||||
|
int_check_in_hero__checkins as (
|
||||||
|
select * from {{ ref("int_check_in_hero__checkins") }}
|
||||||
|
)
|
||||||
|
|
||||||
|
select
|
||||||
|
id_user_partner,
|
||||||
|
extract('year' from created_date_utc) as year,
|
||||||
|
extract('month' from created_date_utc) as month,
|
||||||
|
id_currency,
|
||||||
|
currency_code,
|
||||||
|
sum(booking_fee_in_local_currency) as total_fee_in_local_currency,
|
||||||
|
sum(booking_fee_in_gbp) as total_fee_in_gbp,
|
||||||
|
count(distinct id_record) as number_of_requests,
|
||||||
|
company_name,
|
||||||
|
user_email
|
||||||
|
from int_check_in_hero__checkins
|
||||||
|
group by 1, 2, 3, 4, 5, 9, 10
|
||||||
|
|
@ -41,6 +41,36 @@ models:
|
||||||
to: ref('stg_core__currency')
|
to: ref('stg_core__currency')
|
||||||
field: id_currency
|
field: id_currency
|
||||||
|
|
||||||
|
- name: currency_code
|
||||||
|
data_type: character varying
|
||||||
|
description: Currency ISO 4217 code used by user.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: booking_fee_in_local_currency
|
||||||
|
data_type: numeric
|
||||||
|
description: "Fee charged to the user for each booking in the local currency."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
|
- name: exchange_rate_to_gbp
|
||||||
|
data_type: numeric
|
||||||
|
description: "Exchange rate used to convert the local currency to GBP."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
|
- name: booking_fee_in_gbp
|
||||||
|
data_type: numeric
|
||||||
|
description: "Total fee charged to the user for the month in gbp."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
- name: guest_last_name
|
- name: guest_last_name
|
||||||
data_type: text
|
data_type: text
|
||||||
description: Last name of the guest checking in.
|
description: Last name of the guest checking in.
|
||||||
|
|
@ -166,3 +196,81 @@ models:
|
||||||
description: Date when the record was created.
|
description: Date when the record was created.
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: int_check_in_hero__user_monthly_fee
|
||||||
|
description: |
|
||||||
|
Table that shows the total monthly fee for each user.
|
||||||
|
These charges are calculated based on the amount of request created
|
||||||
|
for each user partner that will be invoiced at the beginning of the
|
||||||
|
following month.
|
||||||
|
columns:
|
||||||
|
- name: id_user_partner
|
||||||
|
data_type: text
|
||||||
|
description: |
|
||||||
|
Identifier for the partner user associated with the check-in.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: year
|
||||||
|
data_type: integer
|
||||||
|
description: |
|
||||||
|
Year when the charges are created. This is obtained from the
|
||||||
|
creation date of each record.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: month
|
||||||
|
data_type: integer
|
||||||
|
description: |
|
||||||
|
Month number when the charges are created. This is obtained from the
|
||||||
|
creation date of each record.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_currency
|
||||||
|
data_type: bigint
|
||||||
|
description: "Id of the currency, works as a foreign key to the
|
||||||
|
currency table"
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- relationships:
|
||||||
|
to: ref('stg_core__currency')
|
||||||
|
field: id_currency
|
||||||
|
|
||||||
|
- name: currency_code
|
||||||
|
data_type: character varying
|
||||||
|
description: Currency ISO 4217 code used by user.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: total_fee_in_local_currency
|
||||||
|
data_type: numeric
|
||||||
|
description: "Total fee charged to the user for the month in the local currency."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
|
- name: total_fee_in_gbp
|
||||||
|
data_type: numeric
|
||||||
|
description: "Total fee charged to the user for the month in gbp."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
|
- name: number_of_requests
|
||||||
|
data_type: numeric
|
||||||
|
description: "Count of requests created by the user partner for the month."
|
||||||
|
data_tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
strictly: true
|
||||||
|
|
||||||
|
- name: company_name
|
||||||
|
data_type: text
|
||||||
|
description: Company name of partner user.
|
||||||
|
|
||||||
|
- name: user_email
|
||||||
|
data_type: text
|
||||||
|
description: Email address of the user associated with the check-in.
|
||||||
|
|
|
||||||
|
|
@ -3,11 +3,13 @@
|
||||||
with
|
with
|
||||||
stg_core__apim_user as (select * from {{ ref("stg_core__apim_user") }}),
|
stg_core__apim_user as (select * from {{ ref("stg_core__apim_user") }}),
|
||||||
stg_core__apim_user_type as (select * from {{ ref("stg_core__apim_user_type") }}),
|
stg_core__apim_user_type as (select * from {{ ref("stg_core__apim_user_type") }}),
|
||||||
stg_core__user as (select * from {{ ref("stg_core__user") }})
|
stg_core__user as (select * from {{ ref("stg_core__user") }}),
|
||||||
|
stg_core__currency as (select * from {{ ref("stg_core__currency") }})
|
||||||
select
|
select
|
||||||
au.id_apim_user,
|
au.id_apim_user,
|
||||||
au.id_apim_user_type,
|
au.id_apim_user_type,
|
||||||
u.id_account_currency as id_currency,
|
u.id_account_currency as id_currency,
|
||||||
|
c.iso4217_code as currency_code,
|
||||||
au.json_document_user_data ->> 'DealId' as id_deal,
|
au.json_document_user_data ->> 'DealId' as id_deal,
|
||||||
au.json_document_user_data ->> 'AccountType' as account_type,
|
au.json_document_user_data ->> 'AccountType' as account_type,
|
||||||
au.json_document_user_data ->> 'ClientMarkup' as client_markup,
|
au.json_document_user_data ->> 'ClientMarkup' as client_markup,
|
||||||
|
|
@ -24,3 +26,4 @@ inner join
|
||||||
on au.id_apim_user_type = aut.id_apim_user_type
|
on au.id_apim_user_type = aut.id_apim_user_type
|
||||||
and upper(aut.user_type_name) = '{{ api_name }}'
|
and upper(aut.user_type_name) = '{{ api_name }}'
|
||||||
inner join stg_core__user u on au.id_apim_user = u.id_user
|
inner join stg_core__user u on au.id_apim_user = u.id_user
|
||||||
|
inner join stg_core__currency c on u.id_account_currency = c.id_currency
|
||||||
|
|
|
||||||
|
|
@ -4806,6 +4806,12 @@ models:
|
||||||
to: ref('stg_core__currency')
|
to: ref('stg_core__currency')
|
||||||
field: id_currency
|
field: id_currency
|
||||||
|
|
||||||
|
- name: currency_code
|
||||||
|
data_type: character varying
|
||||||
|
description: Currency ISO 4217 code used by user.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
- name: id_deal
|
- name: id_deal
|
||||||
data_type: text
|
data_type: text
|
||||||
description: ""
|
description: ""
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue