diff --git a/models/intermediate/int_core__verification_payments.sql b/models/intermediate/int_core__verification_payments.sql new file mode 100644 index 0000000..d5002b4 --- /dev/null +++ b/models/intermediate/int_core__verification_payments.sql @@ -0,0 +1,47 @@ +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__payment as (select * from {{ ref("stg_core__payment") }}), + stg_core__payment_status as (select * from {{ ref("stg_core__payment_status") }}), + int_hardcoded_historical_currency_rates as ( + select * from {{ ref("int_hardcoded_historical_currency_rates") }} + ) +select + vtp.id_verification_to_payment, + vtp.id_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, + vtp.id_guest_user, + vtp.id_verification, + vpt.verification_payment_type, + p.amount as amount_in_txn_currency, + p.currency, + (p.amount * r.rate) as amount_in_gbp, + ps.payment_status, + p.notes +from stg_core__verification_to_payment vtp +left join stg_core__payment p on vtp.id_payment = p.id_payment +left join + stg_core__verification_payment_type vpt + on vtp.id_verification_payment_type = vpt.id_verification_payment_type +left join stg_core__payment_status ps on p.id_payment_status = ps.id_payment_status +left join + int_hardcoded_historical_currency_rates r + on p.paid_date_utc = r.rate_date + and p.currency = r.from_currency + and r.to_currency = 'GBP' diff --git a/models/intermediate/int_hardcoded_historical_currency_rates.sql b/models/intermediate/int_hardcoded_historical_currency_rates.sql index 993df91..32d225e 100644 --- a/models/intermediate/int_hardcoded_historical_currency_rates.sql +++ b/models/intermediate/int_hardcoded_historical_currency_rates.sql @@ -1,7 +1,7 @@ with hardcoded_rates as (select * from {{ ref("stg_seed__hardcoded_currency_rates") }}), dates as (select * from {{ ref("int_dates") }}) -select d.date_day, r.* +select d.date_day as rate_date, r.* from dates d cross join hardcoded_rates r -where d.date_day between '2020-01-01' and '2025-12-31' +where d.date_day > cast('2020-01-01' as date) diff --git a/models/reporting/core/core__verification_payments.sql b/models/reporting/core/core__verification_payments.sql new file mode 100644 index 0000000..5297fa0 --- /dev/null +++ b/models/reporting/core/core__verification_payments.sql @@ -0,0 +1,27 @@ +with + int_core__verification_payments as ( + select * from {{ ref("int_core__verification_payments") }} + ) +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.amount_in_txn_currency as amount_in_txn_currency, + vp.currency as currency, + vp.amount_in_gbp as amount_in_gbp, + vp.payment_status as payment_status, + vp.notes as notes +from int_core__verification_payments vp diff --git a/models/reporting/core/schema.yaml b/models/reporting/core/schema.yaml new file mode 100644 index 0000000..7cfa5ed --- /dev/null +++ b/models/reporting/core/schema.yaml @@ -0,0 +1,110 @@ +version: 2 + +models: + - name: core__verification_payments + description: | + Payments that have happened as part of the Guest Journey. + + Each record matches one payment in a guest journey. For example, if a guest pays a fee and a deposit for a booking, this table will hold two records. + + Lookups to dimensions have been denormalized. + + The data is mostly coming from Superhog, with money conversion happening through hardcoded rates. + columns: + - name: id_verification_to_payment + data_type: bigint + description: Superhog id for the record that relates this Payment to a Verification. + + - name: id_payment + data_type: bigint + description: Superhog id for this Payment. + + - name: is_refundable + data_type: boolean + description: Whether they payment is refundable or not. + + - name: payment_due_at_utc + data_type: timestamp without time zone + description: The point in time at which this payment had to be paid. + + - name: payment_due_date_utc + data_type: date + description: The date on which this payment had to be paid. + + - name: payment_paid_at_utc + data_type: timestamp without time zone + description: The point in time at which this payment was paid. + + - name: payment_paid_date_utc + data_type: date + description: The date on which this payment was paid. + + - name: payment_reference + data_type: character varying + description: | + The payment reference code in the payment processor. + + For Acquired, this is typically and 10-12 digits number. + + For Stripe, this is a payment intent code. This is formatted as `pi_3OieViJK46Ulzq6A16IWxeW5`, with the part after `pi_` being 24 digits long. + + You can use the Stripe code to match this payment with our Stripe records. + + - name: refund_due_at_utc + data_type: timestamp without time zone + description: The point in time at which this payment had to be refunded. + + - name: refund_due_date_utc + data_type: date + description: The date on which this payment had to be refunded. + + - name: payment_refunded_at_utc + data_type: timestamp without time zone + description: The point in time at which this payment was refunded. + + - name: payment_refunded_date_utc + data_type: date + description: The date on which this payment was refunded. + + - name: refund_payment_reference + data_type: character varying + description: | + The payment reference for the refund in the payment processor. + + For Acquired, this is typically and 10-12 digits number. + + For Stripe, this is a refund code. This is formatted as `pyr_3OieViJK46Ulzq6A16IWxeW5` or `re_3OfWeTJK46Ulzq6A02gVvZuk`. + + You can use the Stripe code to match this refund with our Stripe records. + + - name: id_guest_user + data_type: character varying + description: The UUID of the guest user in the Superhog backend. + + - name: id_verification + data_type: bigint + description: The ID of the verification that generated this payment. + + - name: verification_payment_type + data_type: character varying + description: "The payment type. Can be one of: Waiver, Fee, Deposit, Reschedule, Cancellation." + + - 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. + + - 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. + + - 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. + + - name: payment_status + data_type: character varying + description: "The status of the payment. It can be one of: Paid, Refunded, Refund Failed." + + - name: notes + data_type: character varying + description: Free text description on the payment. Typically, contains explanations for integration issues with the payment processor. diff --git a/models/reporting/core__deal_id_master_list.sql b/models/reporting/core__deal_id_master_list.sql deleted file mode 100644 index 0168283..0000000 --- a/models/reporting/core__deal_id_master_list.sql +++ /dev/null @@ -1,6 +0,0 @@ -with - int_core__deal_id_master_list as ( - select * from {{ ref("int_core__deal_id_master_list") }} - ) -select * -from int_core__deal_id_master_list diff --git a/models/reporting/exposures.yaml b/models/reporting/exposures.yaml new file mode 100644 index 0000000..cd4d04c --- /dev/null +++ b/models/reporting/exposures.yaml @@ -0,0 +1,20 @@ +version: 2 + +exposures: + + - name: guest_payments_report + label: Guest Payments Report + type: dashboard + maturity: low + url: Pending + description: | + + A PBI report showcasing data around payments made by Guests during the Guest Journey. + + depends_on: + - ref('dates') + - ref('core__verification_payments') + + owner: + name: Pablo Martin + email: pablo.martin@superhog.com \ No newline at end of file diff --git a/models/reporting/general/dates.sql b/models/reporting/general/dates.sql new file mode 100644 index 0000000..d351885 --- /dev/null +++ b/models/reporting/general/dates.sql @@ -0,0 +1 @@ +with dates as (select * from {{ ref("int_dates") }}) select * from dates diff --git a/models/reporting/general/schema.yaml b/models/reporting/general/schema.yaml new file mode 100644 index 0000000..8d7464a --- /dev/null +++ b/models/reporting/general/schema.yaml @@ -0,0 +1,166 @@ +version: 2 + +models: + - name: dates + description: | + A dates dimension. Each record represents one calendar day. + + All othe columns have handy representations of the date, its subcomponents, and other relative dates. + + This table is generated with the dbt date package: https://hub.getdbt.com/calogica/dbt_date/latest/. + columns: + - name: date_day + data_type: date + description: The date this record represents. All relative dates are relative to this. All derived date components are derived from this. + + - name: prior_date_day + data_type: date + description: The day before date day. + + - name: next_date_day + data_type: date + description: The day after date day. + + - name: prior_year_date_day + data_type: date + description: The same day of the same month, but in the previous year. If date day is Feb 29th, this col returns Feb 28th. + + - name: prior_year_over_year_date_day + data_type: date + description: The day placed 365 days before the date day. Behaves a bit funny with leap years. + + - name: day_of_week + data_type: integer + description: The day of the week as a number, were Monday is 1 and Sunday is 7. + + - name: day_of_week_name + data_type: text + description: The full name of the day of the week. + + - name: day_of_week_name_short + data_type: text + description: The day of the week as a 3 digit shortened version. + + - name: day_of_month + data_type: integer + description: The day of the month as a number. + + - name: day_of_year + data_type: integer + description: The day of the year as a number, where January 1st is 1 and December 31st is 365/366. + + - name: week_start_date + data_type: date + description: | + The full date for the first day of the week of date day. + + It considers Sunday to be the first day of the week. + + - name: week_end_date + data_type: date + description: | + The full date for the last day of the week of date day. + + It considers Saturday to be the last day of the week. + + - name: prior_year_week_start_date + data_type: date + description: Same as week_start_date, but for the same date day in the previous year. + + - name: prior_year_week_end_date + data_type: date + description: Same as week_end_date, but for the same date day in the previous year. + + - name: week_of_year + data_type: integer + description: The week of the year as a number, where the first week is 1 and the last week is 52/53. + + - name: iso_week_start_date + data_type: date + description: | + The full date for the first day of the week of date day, according to ISO specs. + + It considers Monday to be the first day of the week. + + Read more here: https://en.wikipedia.org/wiki/ISO_week_date + + - name: iso_week_end_date + data_type: date + description: | + The full date for the last day of the week of date day, according to ISO specs. + + It considers Sunday to be the last day of the week. + + Read more here: https://en.wikipedia.org/wiki/ISO_week_date + + - name: prior_year_iso_week_start_date + data_type: date + description: "Read more here: https://en.wikipedia.org/wiki/ISO_week_date" + + - name: prior_year_iso_week_end_date + data_type: date + description: "Read more here: https://en.wikipedia.org/wiki/ISO_week_date" + + - name: iso_week_of_year + data_type: integer + description: "Read more here: https://en.wikipedia.org/wiki/ISO_week_date" + + - name: prior_year_week_of_year + data_type: integer + description: "" + + - name: prior_year_iso_week_of_year + data_type: integer + description: "Read more here: https://en.wikipedia.org/wiki/ISO_week_date" + + - name: month_of_year + data_type: integer + description: The month date day belongs to as a number (1 for Jan, 12 for Dec). + + - name: month_name + data_type: text + description: The month date day belongs to in English. + + - name: month_name_short + data_type: text + description: The month date day belongs to as a 3 digit shortened version. + + - name: month_start_date + data_type: date + description: The full date for the first day of the month. + + - name: month_end_date + data_type: date + description: The full date for the last day of the month. + + - name: prior_year_month_start_date + data_type: date + description: The full date for the first day of the same month last year. + + - name: prior_year_month_end_date + data_type: date + description: The full date for the last day of the same month last year. + + - name: quarter_of_year + data_type: integer + description: The quarter date day belongs to as a number (1 for Q1, 4 for Q4). + + - name: quarter_start_date + data_type: date + description: The full date for the first date of the quarter. + + - name: quarter_end_date + data_type: date + description: The full date for the last date of the quarter. + + - name: year_number + data_type: integer + description: The year date day belongs to as a number. + + - name: year_start_date + data_type: date + description: The full date for the first day of the year. + + - name: year_end_date + data_type: date + description: The full date for the last day of the year. diff --git a/models/staging/core/_core_sources.yml b/models/staging/core/_core_sources.yml index 76b709c..b61b8ca 100644 --- a/models/staging/core/_core_sources.yml +++ b/models/staging/core/_core_sources.yml @@ -99,9 +99,9 @@ sources: - name: CreatedUserId data_type: character varying quote: True - description: | + description: | A user can be created by another user. If this user has been created by another user, this is the UUID of the creator. - + Else, this is null. tests: - dbt_expectations.expect_column_values_to_match_regex: @@ -169,3 +169,11 @@ sources: description: "{{ doc('_airbyte_meta_desc') }}" - name: superhog_user identifier: SuperhogUser + - name: VerificationToPayment + identifier: VerificationToPayment + - name: VerificationPaymentType + identifier: VerificationPaymentType + - name: Payment + identifier: Payment + - name: PaymentStatus + identifier: PaymentStatus diff --git a/models/staging/core/stg_core__payment.sql b/models/staging/core/stg_core__payment.sql new file mode 100644 index 0000000..4f83a08 --- /dev/null +++ b/models/staging/core/stg_core__payment.sql @@ -0,0 +1,25 @@ +with + raw_payment as (select * from {{ source("core", "Payment") }}), + sgt_core__payment as ( + select + {{ adapter.quote("Notes") }} as notes, + {{ adapter.quote("Amount") }} as amount, + {{ adapter.quote("PaymentId") }} as id_payment, + {{ adapter.quote("PaymentRef") }} as payment_reference, + {{ adapter.quote("RefundDate") }} as refunded_at_utc, + cast({{ adapter.quote("RefundDate") }} as date) as refunded_date_utc, + {{ adapter.quote("CreatedDate") }} as created_at_utc, + cast({{ adapter.quote("CreatedDate") }} as date) as created_date_utc, + {{ adapter.quote("CurrencyIso") }} as currency, + {{ adapter.quote("PaymentDate") }} as paid_at_utc, + cast({{ adapter.quote("PaymentDate") }} as date) as paid_date_utc, + {{ adapter.quote("UpdatedDate") }} as updated_at_utc, + cast({{ adapter.quote("UpdatedDate") }} as date) as updated_date_utc, + {{ adapter.quote("PaymentStatusId") }} as id_payment_status, + {{ adapter.quote("RefundPaymentRef") }} as refund_payment_reference, + {{ adapter.quote("PaymentProviderId") }} as id_payment_provider, + {{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc + from raw_payment + ) +select * +from sgt_core__payment diff --git a/models/staging/core/stg_core__payment_status.sql b/models/staging/core/stg_core__payment_status.sql new file mode 100644 index 0000000..5a2dfd4 --- /dev/null +++ b/models/staging/core/stg_core__payment_status.sql @@ -0,0 +1,12 @@ +with + raw_payment_status as (select * from {{ source("core", "PaymentStatus") }}), + stg_core__payment_status as ( + select + {{ adapter.quote("Id") }} as id_payment_status, + {{ adapter.quote("FullName") }} as payment_status, + {{ adapter.quote("_airbyte_extracted_at") }}dwh_extracted_at_utc + + from raw_payment_status + ) +select * +from stg_core__payment_status diff --git a/models/staging/core/stg_core__verification_payment_type.sql b/models/staging/core/stg_core__verification_payment_type.sql new file mode 100644 index 0000000..0932dc4 --- /dev/null +++ b/models/staging/core/stg_core__verification_payment_type.sql @@ -0,0 +1,14 @@ +with + raw_verificationpaymenttype as ( + select * from {{ source("core", "VerificationPaymentType") }} + ), + stg_core__verification_payment_type as ( + select + {{ adapter.quote("Id") }} as id_verification_payment_type, + {{ adapter.quote("Name") }} as verification_payment_type, + {{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc + + from raw_verificationpaymenttype + ) +select * +from stg_core__verification_payment_type diff --git a/models/staging/core/stg_core__verification_to_payment.sql b/models/staging/core/stg_core__verification_to_payment.sql new file mode 100644 index 0000000..10c5c8f --- /dev/null +++ b/models/staging/core/stg_core__verification_to_payment.sql @@ -0,0 +1,27 @@ +with + raw_verificationtopayment as ( + select * from {{ source("core", "VerificationToPayment") }} + ), + stg_core__verification_to_payment as ( + select + {{ adapter.quote("Id") }} as id_verification_to_payment, + {{ adapter.quote("PaymentId") }} as id_payment, + {{ adapter.quote("Refundable") }} as is_refundable, + {{ adapter.quote("CreatedDate") }} as created_at_utc, + cast({{ adapter.quote("CreatedDate") }} as date) as created_date_utc, + {{ adapter.quote("UpdatedDate") }} as updated_at_utc, + cast({{ adapter.quote("UpdatedDate") }} as date) as updated_date_utc, + {{ adapter.quote("RefundDueDate") }} as refund_due_at_utc, + cast({{ adapter.quote("RefundDueDate") }} as date) as refund_due_date_utc, + {{ adapter.quote("PaymentDueDate") }} as payment_due_at_utc, + cast({{ adapter.quote("PaymentDueDate") }} as date) as payment_due_date_utc, + {{ adapter.quote("SuperhogUserId") }} as id_guest_user, + {{ adapter.quote("VerificationId") }} as id_verification, + {{ adapter.quote("VerificationPaymentTypeId") }} + as id_verification_payment_type, + {{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc + + from raw_verificationtopayment + ) +select * +from stg_core__verification_to_payment