diff --git a/models/intermediate/core/int_core__guest_satisfaction_responses.sql b/models/intermediate/core/int_core__guest_satisfaction_responses.sql index eb4eb49..e751200 100644 --- a/models/intermediate/core/int_core__guest_satisfaction_responses.sql +++ b/models/intermediate/core/int_core__guest_satisfaction_responses.sql @@ -1,6 +1,6 @@ with int_core__verification_payments as ( - select * from {{ ref("int_core__verification_payments") }} + select * from {{ ref("int_core__verification_payments", version=2) }} ), stg_core__guest_satisfaction_responses as ( select * from {{ ref("stg_core__guest_satisfaction_responses") }} diff --git a/models/intermediate/core/int_core__payaway.sql b/models/intermediate/core/int_core__payaway.sql new file mode 100644 index 0000000..918c54f --- /dev/null +++ b/models/intermediate/core/int_core__payaway.sql @@ -0,0 +1,19 @@ +with + stg_core__payaway as (select * from {{ ref("stg_core__payaway") }}), + stg_core__currency as (select * from {{ ref("stg_core__currency") }}) + +-- replace currency +select + pa.id_payaway_plan, + pa.id_user_host, + pa.start_at_utc, + pa.end_at_utc, + pa.has_no_end_date, + pa.payaway_percentage, + pa.payaway_minimum_commission_local_curr, + c.iso4217_code as currency, + pa.created_at_utc, + pa.updated_at_utc, + pa.dwh_extracted_at_utc +from stg_core__payaway pa +left join stg_core__currency c on pa.id_currency = c.id_currency diff --git a/models/intermediate/core/int_core__payaway_per_month_user.sql b/models/intermediate/core/int_core__payaway_per_month_user.sql new file mode 100644 index 0000000..dceb0e0 --- /dev/null +++ b/models/intermediate/core/int_core__payaway_per_month_user.sql @@ -0,0 +1,51 @@ +with + int_core__payaway as (select * from {{ ref("int_core__payaway") }}), + int_dates as (select * from {{ ref("int_dates") }}), + active_payaway_per_month as ( + select distinct + pa.id_payaway_plan, + pa.id_user_host, + pa.start_at_utc, + pa.end_at_utc, + pa.created_at_utc, + d.month_start_date as active_in_month_start_date_utc, + d.month_end_date as active_in_month_end_date_utc + from int_core__payaway pa + inner join + int_dates d + on d.date_day + between pa.start_at_utc and coalesce(pa.end_at_utc, '2099-12-31T23:59:59Z') + -- open ended plans have null values, so we apply this to make the + -- between work + where + d.date_day < (date_trunc('month', current_date) + interval '1 month')::date + -- no sense in matching stuff in the future. The above statement returns + -- the first day of next month + ), + sorted_payaway_plans as ( + select + id_payaway_plan, + id_user_host, + start_at_utc, + end_at_utc, + created_at_utc, + active_in_month_start_date_utc, + active_in_month_end_date_utc, + row_number() over ( + partition by id_user_host, active_in_month_end_date_utc + order by created_at_utc desc + -- the latest active, created plan is the one that will be + -- valid for the month + ) as rn + from active_payaway_per_month + ) +select + id_payaway_plan, + id_user_host, + start_at_utc, + end_at_utc, + created_at_utc, + active_in_month_start_date_utc, + active_in_month_end_date_utc +from sorted_payaway_plans +where rn = 1 diff --git a/models/intermediate/core/int_core__verification_payments.sql b/models/intermediate/core/int_core__verification_payments_v1.sql similarity index 100% rename from models/intermediate/core/int_core__verification_payments.sql rename to models/intermediate/core/int_core__verification_payments_v1.sql diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 8a57965..222d707 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -932,7 +932,7 @@ models: date before a starting date. - name: int_core__verification_payments - latest_version: 1 + latest_version: 2 description: >- A simplified table that holds guest journey payments with details around when they happen, what service was being paid, what was the related @@ -1020,6 +1020,8 @@ models: versions: - v: 1 deprecation_date: 2024-10-15 00:00:00.00+00:00 + config: + alias: int_core__verification_payments - v: 2 columns: @@ -3184,6 +3186,81 @@ models: plans happened during that month. tests: - not_null + - name: int_core__payaway_per_month_user + description: | + This model contains the payaway plans that were considered as active + for the invoicing process each month. This is, given that more than + one plan coexist within the same month, we take the one plan that + was active at the end of the month. This is the one that should apply for + the invoicing of that month, indisctintly of the fact that there was other + plans active before. + + The time scope of the model is limited to the current month. This means + that, even though some plans will end in future dates or have no planned + end date, this table will only reflect activeness within months up to the + current month. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - id_user_host + - id_payaway_plan + - active_in_month_start_date_utc + + columns: + - name: id_payaway_plan + data_type: bigint + description: | + The unique identifier of this table, representing + the identifier of the payaway plan. + tests: + - not_null + + - name: id_user_host + data_type: string + description: | + The unique identifier of the user host that has + a price plan. + tests: + - not_null + + - name: start_at_utc + data_type: timestamp + description: | + Original timestamp of when a given plan started to be active. + tests: + - not_null + + - name: end_at_utc + data_type: timestamp + description: | + Original timestamp of when a given plan stopped being active. If it's + null, it means the plan is open ended (has no planned end date yet). + + - name: created_at_utc + data_type: timestamp + description: | + Original timestamp of when a given plan was created. + tests: + - not_null + + - name: active_in_month_start_date_utc + data_type: date + description: | + Date that refers to the first day of the month on which we will + consider a plan as active. If we're interested in retrieving the + information from June, this date will be the 1st of June. + tests: + - not_null + + - name: active_in_month_end_date_utc + data_type: date + description: | + Date that refers to the last day of the month on which we will + consider a plan as active. If we're interested in retrieving the + information from June, this date will be the 30th of June. + tests: + - not_null - name: int_core__deal description: | @@ -3252,3 +3329,89 @@ models: description: | Informative field of how many different billing countries are associated to this Deal based on the user account configuration. + - name: int_core__payaway + description: | + Contains all the PayAway plans, which are basically the settings for + host-takes-waiver plans with our host customers. All plans have a start + and end point in time, which means that any waivers that happen during + the range of plan should use the settings of this plan as a reference. + + Plans can be open ended, as in not having a specified end in time. This + just means they are indefinitely active until someone changes it. + + Plans can also have a planned end time which sits in the future. + columns: + - name: id_payaway_plan + data_type: bigint + description: "The unique id for this plan." + tests: + - not_null + - unique + + - name: id_user_host + data_type: character varying + description: "The Superhog ID of the host user this record applies to." + + - name: start_at_utc + data_type: timestamp without time zone + description: + The point in time in which this plan became active. It can never be + null. + + - name: end_at_utc + data_type: timestamp without time zone + description: + The point in time in which this plan will stop being active. It can + be null, which means the plan has no planned end date yet. Should this + column have a value, it should always be after the start time of the + plan. + + - name: has_no_end_date + data_type: boolean + description: Syntactic sugar for checking if the plan has a specified end date. + + - name: payaway_percentage + data_type: numeric + description: | + The percentage of the Waiver payments that Superhog will keep as a + a fee. Should be between 0% and a 100%. 0% is a valid amount. + + This means that the Superhog fee is computed as: + Waiver Amount * payaway_percentage. + + If the amount that comes out of this calculation is smaller than the + amount in column payaway_minimum_commission_local_curr, then the + Superhog fee becomes payaway_minimum_commission_local_curr instead. + So, the final logic becomes: + MAX( + Waiver Amount * payaway_percentage, + payaway_minimum_commission_local_curr + ) + + - name: payaway_minimum_commission_local_curr + data_type: numeric + description: + The minimum fee that we take from each waiver payment, specified in + the currency of the guest payment (so if this record is in dollars, it + means it applies to guest payments made in dollars). We will never + charge less than this. This can be 0. + + - name: currency + data_type: character varying + description: + The ISO 4217 code for the currency of this record. Must always be + filled, otherwise the records is meaningless. + tests: + - not_null + + - name: created_at_utc + data_type: timestamp without time zone + description: Timestamp of when the pay away plan was created. + + - name: updated_at_utc + data_type: timestamp without time zone + description: Timestamp of when the pay away plan to currency was last updated + + - name: dwh_extracted_at_utc + data_type: timestamp with time zone + description: Timestamp of when this data was extracted into DWH. diff --git a/models/reporting/core/core__verification_payments.sql b/models/reporting/core/core__verification_payments_v1.sql similarity index 93% rename from models/reporting/core/core__verification_payments.sql rename to models/reporting/core/core__verification_payments_v1.sql index 5297fa0..afd5715 100644 --- a/models/reporting/core/core__verification_payments.sql +++ b/models/reporting/core/core__verification_payments_v1.sql @@ -1,6 +1,6 @@ with int_core__verification_payments as ( - select * from {{ ref("int_core__verification_payments") }} + select * from {{ ref("int_core__verification_payments", version=1) }} ) select vp.id_verification_to_payment as id_verification_to_payment, diff --git a/models/reporting/core/core__verification_payments_v2.sql b/models/reporting/core/core__verification_payments_v2.sql new file mode 100644 index 0000000..4db5f13 --- /dev/null +++ b/models/reporting/core/core__verification_payments_v2.sql @@ -0,0 +1,29 @@ +with + int_core__verification_payments as ( + select * from {{ ref("int_core__verification_payments", version=2) }} + ) +select + vp.id_verification_to_payment as id_verification_to_payment, + vp.id_payment as id_payment, + vp.is_refundable as is_refundable, + vp.payment_due_at_utc as payment_due_at_utc, + vp.payment_due_date_utc as payment_due_date_utc, + vp.payment_paid_at_utc as payment_paid_at_utc, + vp.payment_paid_date_utc as payment_paid_date_utc, + vp.payment_reference as payment_reference, + vp.refund_due_at_utc as refund_due_at_utc, + vp.refund_due_date_utc as refund_due_date_utc, + vp.payment_refunded_at_utc as payment_refunded_at_utc, + vp.payment_refunded_date_utc as payment_refunded_date_utc, + vp.refund_payment_reference as refund_payment_reference, + vp.id_guest_user as id_guest_user, + vp.id_verification as id_verification, + vp.verification_payment_type as verification_payment_type, + vp.total_amount_in_txn_currency as total_amount_in_txn_currency, + vp.amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency, + vp.currency as currency, + vp.total_amount_in_gbp as total_amount_in_gbp, + vp.amount_without_taxes_in_gbp as amount_without_taxes_in_gbp, + vp.payment_status as payment_status, + vp.notes as notes +from int_core__verification_payments vp diff --git a/models/reporting/core/core__vr_check_in_cover.sql b/models/reporting/core/core__vr_check_in_cover.sql index 3d01669..d137d9d 100644 --- a/models/reporting/core/core__vr_check_in_cover.sql +++ b/models/reporting/core/core__vr_check_in_cover.sql @@ -34,9 +34,6 @@ select amount_without_taxes_in_txn_currency as amount_without_taxes_in_txn_currency, total_amount_in_gbp as total_amount_in_gbp, amount_without_taxes_in_gbp as amount_without_taxes_in_gbp, - total_amount_in_txn_currency as amount_in_txn_currency, -- LEGACY - total_amount_in_gbp as amount_in_gbp, -- LEGACY - checkin_cover_limit_amount_local_curr as checkin_cover_limit_amount_local_curr, checkin_cover_limit_amount_in_gbp as checkin_cover_limit_amount_in_gbp from core__vr_check_in_cover diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index 1b48715..2665c9e 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -2,6 +2,7 @@ version: 2 models: - name: core__verification_payments + latest_version: 2 description: | Payments that have happened as part of the Guest Journey. @@ -29,10 +30,14 @@ models: - name: payment_due_at_utc data_type: timestamp without time zone description: The point in time at which this payment had to be paid. + tests: + - not_null - name: payment_due_date_utc data_type: date description: The date on which this payment had to be paid. + tests: + - not_null - name: payment_paid_at_utc data_type: timestamp without time zone @@ -83,10 +88,14 @@ models: - name: id_guest_user data_type: character varying description: The UUID of the guest user in the Superhog backend. + tests: + - not_null - name: id_verification data_type: bigint description: The ID of the verification that generated this payment. + tests: + - not_null - name: verification_payment_type data_type: character varying @@ -94,24 +103,79 @@ models: - name: amount_in_txn_currency data_type: numeric - description: The payment amount in the currency in which the transaction actually happened. If the guest paid in Australian Dollars, this is measured in AUD. + description: The payment amount in the currency in which the transaction actually happened. If the guest paid in Australian Dollars, this is measured in AUD. (To be decommissioned) + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false - name: currency data_type: character varying description: The currency in which the transaction actually happened. If the guest paid in Australian Dollars, this is measured in AUD. + tests: + - not_null - name: amount_in_gbp data_type: numeric description: The payment amount value, converted to GBP, using the exchange rate for the day on which the payment happened. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false - name: payment_status data_type: character varying - description: "The status of the payment. It can be one of: Paid, Refunded, Refund Failed." + description: "The status of the payment. It can be one of: Paid, Refunded, Refund Failed, Cancelled, Paid Manually, Unpaid." + tests: + - not_null - name: notes data_type: character varying description: Free text description on the payment. Typically, contains explanations for integration issues with the payment processor. + versions: + - v: 1 + deprecation_date: 2024-10-15 00:00:00.00+00:00 + config: + alias: core__verification_payments + + - v: 2 + columns: + - name: total_amount_in_txn_currency + data_type: numeric + description: The payment amount in the currency in which the transaction actually happened. If the guest paid in Australian Dollars, this is measured in AUD. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: amount_without_taxes_in_txn_currency + data_type: numeric + description: The payment amount without taxes in the currency in which the transaction actually happened. If the guest paid in Australian Dollars, this is measured in AUD. (To be decommissioned) + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: total_amount_in_gbp + data_type: numeric + description: The payment amount value, converted to GBP, using the exchange rate for the day on which the payment happened. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: amount_without_taxes_in_gbp + data_type: numeric + description: The payment amount value without taxes, converted to GBP, using the exchange rate for the day on which the payment happened. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - include: all + exclude: [amount_in_txn_currency, amount_in_gbp] + - name: core__bookings description: | @@ -323,19 +387,29 @@ models: description: | The date at which the guest finished the guest journey. - - name: amount_in_txn_currency + - name: total_amount_in_txn_currency data_type: numeric description: | The amount paid by the guest for the check-in cover, in the currency - in which the payment actually took place. + in which the payment actually took place. Tax inclusive. + + - name: amount_without_taxes_in_txn_currency + data_type: numeric + description: | + The equivalent amount paid by the guest for the check-in cover, in the currency + in which the payment actually took place, without taxes. - name: currency data_type: character varying description: The currency used by the guest for the payment. - - name: amount_in_gbp + - name: total_amount_in_gbp data_type: numeric - description: The amount paid by the guest, converted into GBP. + description: The amount paid by the guest, converted into GBP. Tax inclusive. + + - name: amount_without_taxes_in_gbp + data_type: numeric + description: The equivalent amount paid by the guest, converted into GBP and without taxes. - name: payment_status data_type: character varying diff --git a/models/reporting/exposures.yml b/models/reporting/exposures.yml index 79118ff..ce23470 100644 --- a/models/reporting/exposures.yml +++ b/models/reporting/exposures.yml @@ -12,7 +12,7 @@ exposures: depends_on: - ref('dates') - - ref('core__verification_payments') + - ref('core__verification_payments', version=1) owner: name: Pablo Martin diff --git a/models/reporting/xero/schema.yml b/models/reporting/xero/schema.yml index 417efc1..7df3c2e 100644 --- a/models/reporting/xero/schema.yml +++ b/models/reporting/xero/schema.yml @@ -1105,7 +1105,7 @@ models: The transaction currency is defined at the Bank Transaction level, and the values you see in this field should always be the same as the currency of the Bank Transaction this line item belongs to. - - name: xero__bank_transaction_denom_mart.sql + - name: xero__bank_transaction_denom_mart description: | This model is a denormalized mart, which only exists for presentation purposes in a PBI report. diff --git a/models/staging/core/_core_sources.yml b/models/staging/core/_core_sources.yml index dccc25a..426a0bc 100644 --- a/models/staging/core/_core_sources.yml +++ b/models/staging/core/_core_sources.yml @@ -232,4 +232,6 @@ sources: - name: AccommodationToProductBundle identifier: AccommodationToProductBundle - name: ElectronicDepositUser - identifier: ElectronicDepositUser \ No newline at end of file + identifier: ElectronicDepositUser + - name: PayAway + identifier: PayAway diff --git a/models/staging/core/schema.yml b/models/staging/core/schema.yml index 5905c00..2dce224 100644 --- a/models/staging/core/schema.yml +++ b/models/staging/core/schema.yml @@ -391,3 +391,132 @@ models: data_type: timestamp description: | Timestamp of when this data was extracted into DWH. + - name: stg_core__payaway + description: | + Contains all the PayAway plans, which are basically the settings for + host-takes-waiver plans with our host customers. All plans have a start + and end point in time. + + As of today, though, the reality is that our monthly invoicing and + settlement process with hosts only looks at the payaway plan that was + active when a month finished. + + Plans can be open ended, as in not having a specified end in time. This + just means they are indefinitely active until someone changes it. + + Plans can also have a planned end time which sits in the future. + tests: + - dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B: + # The end timestamp should always be after the start timestamp + column_A: end_at_utc + column_B: start_at_utc + or_equal: False + - dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B: + # The updated timestamp should always be equal or after the creation + # timestamp + column_A: updated_at_utc + column_B: created_at_utc + or_equal: True + + columns: + - name: id_payaway_plan + data_type: bigint + description: The unique id for this plan. + tests: + - unique + - not_null + + - name: id_currency + data_type: bigint + description: | + The Superhog ID of the currency that this record applies to. + tests: + - not_null + + - name: id_user_host + data_type: character varying + description: | + The Superhog ID of the host user this record applies to. + tests: + - not_null + + - name: start_at_utc + data_type: timestamp without time zone + description: | + The point in time in which this plan became active. It can never be + null. + tests: + - not_null + + - name: end_at_utc + data_type: timestamp without time zone + description: | + The point in time in which this plan will stop being active. It can be + null, which means the plan has no planned end date yet. Should this + column have a value, it should always be after the start time of the + plan. + + - name: has_no_end_date + data_type: boolean + description: | + Syntactic sugar for checking if the plan has a specified end date. + tests: + - not_null + + - name: payaway_percentage + data_type: numeric + description: | + The percentage of the Waiver payments that Superhog will keep as a + a fee. Should be between 0% and a 100%. 0% is a valid amount. + + This means that the Superhog fee is computed as: + Waiver Amount * payaway_percentage. + + If the amount that comes out of this calculation is smaller than the + amount in column payaway_minimum_commission_local_curr, then the + Superhog fee becomes payaway_minimum_commission_local_curr instead. + So, the final logic becomes: + MAX( + Waiver Amount * payaway_percentage, + payaway_minimum_commission_local_curr + ) + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: 1 + strictly: false + + - name: payaway_minimum_commission_local_curr + data_type: numeric + description: | + The minimum fee that we take from each waiver payment, specified in + the currency of the guest payment (so if this record is in dollars, it + means it applies to guest payments made in dollars). We will never + charge less than this. This can be 0. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: created_at_utc + data_type: timestamp + description: | + Timestamp of when the pay away plan was created. + tests: + - not_null + + - name: updated_at_utc + data_type: timestamp + description: | + Timestamp of when the pay away plan to currency was last updated + tests: + - not_null + + - name: dwh_extracted_at_utc + data_type: timestamp + description: | + Timestamp of when this data was extracted into DWH. + tests: + - not_null diff --git a/models/staging/core/stg_core__payaway.sql b/models/staging/core/stg_core__payaway.sql new file mode 100644 index 0000000..115ef7e --- /dev/null +++ b/models/staging/core/stg_core__payaway.sql @@ -0,0 +1,21 @@ +with + raw_payaway as (select * from {{ source("core", "PayAway") }}), + stg_core__payaway as ( + select + {{ adapter.quote("Id") }} as id_payaway_plan, + {{ adapter.quote("CurrencyId") }} as id_currency, + {{ adapter.quote("SuperhogUserId") }} as id_user_host, + {{ adapter.quote("StartDate") }} as start_at_utc, + {{ adapter.quote("EndDate") }} as end_at_utc, + {{ adapter.quote("EndDate") }} is null as has_no_end_date, + {{ adapter.quote("PayAwayPercentage") }} as payaway_percentage, + {{ adapter.quote("PayAwayMinimumCommission") }} + as payaway_minimum_commission_local_curr, + {{ adapter.quote("CreatedDate") }} as created_at_utc, + {{ adapter.quote("UpdatedDate") }} as updated_at_utc, + {{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc + + from raw_payaway + ) +select * +from stg_core__payaway