From ac73138cf1e9d59370c07bf7f7ae170fe89a4b0e Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Fri, 9 May 2025 10:13:58 +0000 Subject: [PATCH] Merged PR 5171: First version of Guest Product Payments # Description First model for Guest Product Payments. It only contains CIH from Verification Payments (so, the "old" CIH). Some notes: * It does not handle taxes computation. * It converts guest product name to upper case, as the guest product tables are in upper case. I also apply it for payment status, as well as an UNKNOWN status for whenever it's null - we'd need to consider this for the rest of the refactor. * Computation is placed within a CTE. This is intended since at some point this will include also Guest Product Payments that come from Guest Product related tables. * Enhanced documentation with respect to Verification Payments V2. Audit performed: ``` -- THIS GOES INTO AN AUDIT FILE {% set old_query %} select * from dwh_hybrid.intermediate.int_core__guest_product_payments {% endset %} {% set new_query %} select id_verification_to_payment, id_payment, is_refundable, created_at_utc, updated_at_utc, payment_due_at_utc, payment_due_date_utc, payment_paid_at_utc, payment_paid_date_utc, payment_reference, refund_due_at_utc, refund_due_date_utc, payment_refunded_at_utc, payment_refunded_date_utc, refund_payment_reference, id_user_host, id_guest_user as id_user_guest, id_verification, id_verification_request, upper(verification_payment_type) as guest_product_name, currency, total_amount_in_txn_currency, total_amount_in_gbp, coalesce(upper(payment_status),'UNKNOWN') as payment_status, notes from dwh_hybrid.intermediate.int_core__verification_payments_v2 where verification_payment_type = 'CheckInCover' {% endset %} {{ audit_helper.compare_and_classify_query_results( old_query, new_query, primary_key_columns=["id_verification_to_payment"], columns=[ "id_verification_to_payment", "id_payment", "is_refundable", "created_at_utc", "updated_at_utc", "payment_due_at_utc", "payment_due_date_utc", "payment_paid_at_utc", "payment_paid_date_utc", "payment_reference", "refund_due_at_utc", "refund_due_date_utc", "payment_refunded_at_utc", "payment_refunded_date_utc", "refund_payment_reference", "id_user_host", "id_user_guest", "id_verification", "id_verification_request", "guest_product_name", "currency", "total_amount_in_txn_currency", "total_amount_in_gbp", "payment_status", "notes", ], sample_limit=10000000, ) }} ``` # 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 ... --- .../core/int_core__guest_product_payments.sql | 85 +++++++ models/intermediate/core/schema.yml | 228 +++++++++++++++++- 2 files changed, 310 insertions(+), 3 deletions(-) create mode 100644 models/intermediate/core/int_core__guest_product_payments.sql diff --git a/models/intermediate/core/int_core__guest_product_payments.sql b/models/intermediate/core/int_core__guest_product_payments.sql new file mode 100644 index 0000000..0a1eb56 --- /dev/null +++ b/models/intermediate/core/int_core__guest_product_payments.sql @@ -0,0 +1,85 @@ +{% set check_in_cover_as_id_verification_payment = "5" %} +{% set cut_off_date_check_in_cover_as_id_verification_payment = "'2025-06-08'" %} + +with + stg_core__verification_to_payment as ( + select * from {{ ref("stg_core__verification_to_payment") }} + ), + stg_core__verification_payment_type as ( + select * from {{ ref("stg_core__verification_payment_type") }} + ), + stg_core__verification as (select * from {{ ref("stg_core__verification") }}), + stg_core__verification_request as ( + select * from {{ ref("stg_core__verification_request") }} + ), + stg_core__payment as (select * from {{ ref("stg_core__payment") }}), + stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}), + int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }}), + guest_product_payments_from_verification_payments as ( + select + vtp.id_verification_to_payment as id_guest_product_payment, + vtp.id_payment, + vtp.id_verification_to_payment, + vtp.is_refundable, + vtp.created_at_utc, + vtp.updated_at_utc, + vtp.payment_due_at_utc, + vtp.payment_due_date_utc, + p.paid_at_utc as payment_paid_at_utc, + p.paid_date_utc as payment_paid_date_utc, + p.payment_reference, + vtp.refund_due_at_utc, + vtp.refund_due_date_utc, + p.refunded_at_utc as payment_refunded_at_utc, + p.refunded_date_utc as payment_refunded_date_utc, + p.refund_payment_reference, + vr.id_user_host, + vtp.id_guest_user as id_user_guest, + vtp.id_verification, + v.id_verification_request, + upper(vpt.verification_payment_type) as guest_product_name, + 'VERIFICATION_PAYMENT' as guest_product_payment_source, + p.currency, + p.amount as total_amount_in_txn_currency, + (p.amount * r.rate)::decimal(19, 4) as total_amount_in_gbp, + upper(coalesce(ps.payment_status, 'UNKNOWN')) as payment_status, + p.notes + from stg_core__verification_to_payment vtp + inner join + stg_core__verification_payment_type vpt + on vtp.id_verification_payment_type = vpt.id_verification_payment_type + left join stg_core__payment p on vtp.id_payment = p.id_payment + inner join + stg_core__payment_status ps on p.id_payment_status = ps.id_payment_status + inner join + int_simple_exchange_rates r + on vtp.payment_due_date_utc = r.rate_date_utc + and p.currency = r.from_currency + and r.to_currency = 'GBP' + left join stg_core__verification v on vtp.id_verification = v.id_verification + left join + stg_core__verification_request vr + on v.id_verification_request = vr.id_verification_request + where + vtp.id_verification_payment_type + = {{ check_in_cover_as_id_verification_payment }} + -- Following is to enhance the performance of the query once Guest Product + -- payment data follows exclusively the dedicated Guest Product models + and v.created_date_utc + <= date({{ cut_off_date_check_in_cover_as_id_verification_payment }}) + and vtp.created_date_utc + <= date({{ cut_off_date_check_in_cover_as_id_verification_payment }}) + and p.created_date_utc + <= date({{ cut_off_date_check_in_cover_as_id_verification_payment }}) + and vr.created_date_utc + <= date({{ cut_off_date_check_in_cover_as_id_verification_payment }}) + ) +select * +from + guest_product_payments_from_verification_payments + -- This model is expecting to have provide Guest Product Payment data for + -- both old Check-in Cover and new Guest Product models. At the moment, + -- the data is only provided for the "old" Check-in Cover. Once the Guest Product + -- models are in place, we expect to have here a new CTE that is unioned with the + -- one above. + diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index a4e7165..e1f2d7d 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -2666,7 +2666,7 @@ models: description: | Integer-based flag version of total_active_listings_with_active_product_bundle_with_paid_service. - + # To be deleted from here - name: total_listings_with_product_bundle_with_paid_service data_type: integer @@ -2690,7 +2690,6 @@ models: description: | Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service. # To be deleted until here - - name: total_bookings_with_product_bundle data_type: integer description: | @@ -3131,7 +3130,7 @@ models: - DEPOSIT_MANAGEMENT - GUEST_AGREEMENT - PROTECTION - + - name: is_default_service data_type: boolean description: | @@ -6047,3 +6046,226 @@ models: Date of when this record was last updated. data_tests: - not_null + + - name: int_core__guest_product_payments + description: | + A model that holds guest products payments with details around + when they happen, what service was being paid, what was the related + verification request, etc. + + Currency rates are converted to GBP with our simple exchange rates view. + Only amounts with taxes are included in this model. + + (!) At this moment, this model only includes Check In Cover payments made + as Verification Payments. + + columns: + - name: id_guest_product_payment + data_type: bigint + description: | + Unique identifier for the guest product payment. + data_tests: + - unique + - not_null + + - name: id_payment + data_type: bigint + description: | + Unique ID for the payment itself. + data_tests: + - unique + - not_null + + - name: id_verification_to_payment + data_type: bigint + description: | + Identifier for the relation between the payment verification + and the payment. It can be null if the payment is not related + to a verification. + + - name: is_refundable + data_type: boolean + description: | + Indicates whether the payment is refundable or not. + + - name: created_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the payment was created. + It cannot be null. + data_tests: + - not_null + + - name: updated_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the payment was last updated. + It cannot be null. + data_tests: + - not_null + + - name: payment_due_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the payment is due. + It cannot be null. + data_tests: + - not_null + + - name: payment_due_date_utc + data_type: date + description: | + Date of when the payment is due. + It cannot be null. + data_tests: + - not_null + + - name: payment_paid_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the payment was paid. + It can be null if the payment has not been paid yet. + + - name: payment_paid_date_utc + data_type: date + description: | + Date of when the payment was paid. + It can be null if the payment has not been paid yet. + + - name: payment_reference + data_type: character varying + description: | + Reference code associated with the payment. + It can be null if the payment has not been paid yet. + + - name: refund_due_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the refund is due. + It can be null if the payment has not been refunded. + + - name: refund_due_date_utc + data_type: date + description: | + Date of when the refund is due. + It can be null if the payment has not been refunded. + + - name: payment_refunded_at_utc + data_type: timestamp without time zone + description: | + Timestamp of when the payment was refunded. + It can be null if the payment has not been refunded. + + - name: payment_refunded_date_utc + data_type: date + description: | + Date of when the payment was refunded. + It can be null if the payment has not been refunded. + + - name: refund_payment_reference + data_type: character varying + description: | + Reference code associated with the refund payment. + It can be null if the payment has not been refunded. + + - name: id_user_host + data_type: character varying + description: | + Unique identifier of the Host linked to the Verification + Request that has a payment. + It can be null for same-day payments due to different freshness + of the sources used to build this model. + data_tests: + - not_null: + where: "date(created_at_utc) < current_date" + + - name: id_user_guest + data_type: character varying + description: | + Unique identifier of the Guest linked to the Verification + Request that has a payment. + It cannot be null. + data_tests: + - not_null + + - name: id_verification + data_type: bigint + description: | + Unique identifier of the Verification that has a payment. + It can be null if the payment is not related to a verification. + + - name: id_verification_request + data_type: bigint + description: | + Unique identifier of the Verification Request that has a payment. + It can be null if the payment is not related to a verification. + + - name: guest_product_name + data_type: character varying + description: | + Name of the Guest Product associated with the payment. + This corresponds to the internal name, rather than the display name. + It cannot be null. + data_tests: + - not_null + - accepted_values: + values: + - CHECKINCOVER + + - name: guest_product_payment_source + data_type: character varying + description: | + Backend source of the Guest Product payment. + This helps identify the backend tables that are used to track this + payment. + It cannot be null. + At this stage, it only includes the source "VERIFICATION_PAYMENT". + data_tests: + - not_null + - accepted_values: + values: + - VERIFICATION_PAYMENT + + - name: currency + data_type: character varying + description: | + The ISO 4217 currency code (e.g., GBP, USD, EUR) in which the payment + was originally made. + It can be null for same-day payments due to different freshness + of the sources used to build this model. + data_tests: + - not_null: + where: "date(created_at_utc) < current_date" + + - name: total_amount_in_txn_currency + data_type: numeric + description: | + The total amount of the payment in local currency. + This includes taxes if applicable. + + - name: total_amount_in_gbp + data_type: numeric + description: | + The total amount of the payment in GBP. + This includes taxes if applicable. + + - name: payment_status + data_type: character varying + description: | + Current status of the payment (e.g., PAID). + It cannot be null. + data_tests: + - accepted_values: + values: + - PAID + - REFUNDED + - REFUND FAILED + - FAILED WITH RETRY + - FAILED + - UNKNOWN + + - name: notes + data_type: character varying + description: | + Notes or comments associated with the payment. + It can be null if there are no notes.