Merged PR 1798: CheckIn Hero Reporting

A gazillion things to support the check-in hero dashboards.
This commit is contained in:
Pablo Martín 2024-05-07 16:01:58 +00:00
commit 97ef7f2763
16 changed files with 667 additions and 1 deletions

View file

@ -28,6 +28,8 @@ select
b.check_in_date_utc,
b.check_out_at_utc,
b.check_out_date_utc,
b.check_in_at_utc > now() as check_in_sits_in_future,
b.check_out_at_utc > now() as check_out_sits_in_future,
bce.booking_fee_local,
booking_fee_charge_at_utc,
booking_fee_charge_date_utc,

View file

@ -0,0 +1,13 @@
with
stg_core__payment_validation_set_to_currency as (
select * from {{ ref("stg_core__payment_validation_set_to_currency") }}
)
select
pvttoc.local_currency_iso_4217,
pvttoc.checkin_cover_guest_fee_local_curr,
pvttoc.checkin_cover_cover_amount_local_curr
from stg_core__payment_validation_set_to_currency pvttoc
group by
pvttoc.local_currency_iso_4217,
pvttoc.checkin_cover_guest_fee_local_curr,
pvttoc.checkin_cover_cover_amount_local_curr

View file

@ -5,6 +5,7 @@ with
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__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 (
@ -28,6 +29,7 @@ select
p.refund_payment_reference,
vtp.id_guest_user,
vtp.id_verification,
v.id_verification_request,
vpt.verification_payment_type,
p.amount as amount_in_txn_currency,
p.currency,
@ -36,6 +38,7 @@ select
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 v on vtp.id_verification = v.id_verification
left join
stg_core__verification_payment_type vpt
on vtp.id_verification_payment_type = vpt.id_verification_payment_type

View file

@ -0,0 +1,108 @@
/*
Welcome, fellow modeller.
This model exists because, surprisingly, telling whether a guest journey (AKA
Verification Request) is completed or not is rather complex.
This model is built mostly to encapsulate the chaos necessary to determine
this. With the output of this model, we can simply join the final result to
the main Verification Request table and enjoy having this abstracted away.
The original logic was inspired by the SQL Server function
`GetVerificationProgress` that I borrowed from the backend. You can find its
code here:
https://guardhog.visualstudio.com/Superhog/_git/superhog-mono-app?path=/Guardhog.Data/Functions/GetVerificationProgress/202305021429044_GetVerificationProgress.cs
*/
/*
As for the general logic, so that the monster below makes some slight sense:
- We have three possible outcomes: Not Started, Action Required and Complete.
- Not Started records are easy to spot: if there is no associated Guest or
VerificationSet, the Guest Journey wasn't even started.
- Action Required are the tricky bits:
- On one hand, if the VerificationSet contains VerificationTypes
`PaymentValidation` or `Contract`, those need to be completed
WITHIN THE SAME VERIFICATION REQUEST.
- On the other hand, any other Verification Types that are required can be
completed on the same VerificationRequest OR IN ANOTHER ONE (as long as
the guest user is the same)
- So, to spot Action Required records, we:
- Check if `PaymentValidation` or `Contract` were required and not
completed in the same VR.
- Check if any other required VerificationType were required and not
completed on any other VR with the same user.
- Take into account the nuanced meaning of "not completed": it can be
either that the Verification exists but the VerificationState is
different than 1 (Confirmed), OR that there isn't even a created
Verification.
- Finally, whatever doesn't fall into Not Started or Action Required,
is considered Complete.
*/
with
stg_core__verification_request as (
select * from {{ ref("stg_core__verification_request") }}
),
stg_core__verification as (select * from {{ ref("stg_core__verification") }}),
stg_core__verification_set_to_verification_type as (
select * from {{ ref("stg_core__verification_set_to_verification_type") }}
),
stg_core__verification_type as (
select * from {{ ref("stg_core__verification_type") }}
),
expected_verification_types as (
select
vr.id_verification_request,
vr.id_user_guest,
vt.verification_type,
null as id_verification_status
from stg_core__verification_request vr
left join
stg_core__verification_set_to_verification_type vstvt
on vstvt.id_verification_set = vr.id_verification_set
left join
stg_core__verification_type vt
on vstvt.id_verification_type = vt.id_verification_type
),
same_vr_verification_state as (
select vr.id_verification_request, v.verification, v.id_verification_status
from stg_core__verification v
left join
stg_core__verification_request vr
on v.id_verification_request = vr.id_verification_request
where
v.verification in ('PaymentValidation', 'Contract')
and v.id_verification_request is not null
),
by_user_verification_state as (
select distinct vr.id_user_guest, v.verification, v.id_verification_status
from stg_core__verification v
left join
stg_core__verification_request vr
on v.id_verification_request = vr.id_verification_request
where verification not in ('PaymentValidation', 'Contract')
),
completeness_summary as (
select
evt.id_verification_request,
evt.verification_type,
coalesce(
t1.id_verification_status, t2.id_verification_status
) as global_id_verification_status
from expected_verification_types evt
left join
same_vr_verification_state as t1
on evt.id_verification_request = t1.id_verification_request
and evt.verification_type = t1.verification
left join
by_user_verification_state as t2
on evt.id_user_guest = t2.id_user_guest
and evt.verification_type = t2.verification
)
select
id_verification_request,
count(1) as expected_verification_count,
sum(global_id_verification_status) as confirmed_verification_count,
coalesce(
count(1) = sum(global_id_verification_status), false
) as is_verification_request_complete
from completeness_summary
group by id_verification_request

View file

@ -2,7 +2,10 @@ with
stg_core__verification_request as (
select * from {{ ref("stg_core__verification_request") }}
),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }})
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
int_core__verification_request_completeness as (
select * from {{ ref("int_core__verification_request_completeness") }}
)
select
vr.id_verification_request,
vr.uuid_verification_request,
@ -11,6 +14,7 @@ select
vr.id_payment_validation_set,
vr.id_user_guest,
vr.id_user_host,
completeness.is_verification_request_complete,
vr.verification_url,
vr.callback_url,
vr.redirect_url,
@ -46,3 +50,6 @@ select
vr.dwh_extracted_at_utc
from stg_core__verification_request vr
left join int_core__unified_user guest on vr.id_user_guest = guest.id_user
left join
int_core__verification_request_completeness completeness
on vr.id_verification_request = completeness.id_verification_request

View file

@ -0,0 +1,105 @@
with
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
stg_core__verification_set_to_verification_type as (
select * from {{ ref("stg_core__verification_set_to_verification_type") }}
),
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
int_core__check_in_cover_prices as (
select * from {{ ref("int_core__check_in_cover_prices") }}
),
check_in_cover_payments as (
select
id_verification_request,
amount_in_txn_currency,
currency,
amount_in_gbp,
payment_status,
payment_paid_date_utc
from {{ ref("int_core__verification_payments") }}
where
verification_payment_type = 'CheckInCover' -- 5 is check-in cover
and payment_status in ('Paid', 'Refunded')
)
select
vr.id_verification_request,
vr.uuid_verification_request,
vr.id_verification_set,
vr.id_superhog_verified_set,
vr.id_payment_validation_set,
vr.id_user_guest,
vr.id_user_host,
b.id_booking,
b.id_accommodation,
vr.is_verification_request_complete,
(
p.amount_in_txn_currency is not null and not b.check_in_sits_in_future
) as is_past_check_in,
(
p.amount_in_txn_currency is not null
and b.check_in_sits_in_future
and vr.is_verification_request_complete
) as is_awaiting_check_in,
p.amount_in_txn_currency is not null as cover_was_purchased,
(
p.amount_in_txn_currency is null and vr.is_verification_request_complete
) as cover_was_rejected,
vr.verification_url,
vr.callback_url,
vr.redirect_url,
vr.logo,
vr.guest_email,
vr.last_name,
vr.first_name,
vr.guest_phone_number,
vr.telephone_code,
vr.guest_phone_number_2,
b.check_in_at_utc,
b.check_in_date_utc,
b.check_out_at_utc,
b.check_out_date_utc,
vr.verification_start_at_utc,
vr.verification_start_date_utc,
vr.verification_end_at_utc,
vr.verification_end_date_utc,
vr.link_used_at_utc,
vr.link_used_date_utc,
vr.expire_at_utc,
vr.expire_date_utc,
vr.is_deleted,
vr.redirect_name,
vr.id_one_step_link,
vr.success_message,
vr.summary,
vr.rejection_reason,
vr.has_switched_to_mobile,
vr.is_verifier_rejected,
vr.config,
vr.metadata,
vr.created_at_utc,
vr.created_date_utc,
vr.updated_at_utc,
vr.updated_date_utc,
vr.dwh_extracted_at_utc,
p.amount_in_txn_currency,
p.currency,
p.amount_in_gbp,
p.payment_status,
p.payment_paid_date_utc,
ccp.checkin_cover_cover_amount_local_curr,
ccp.checkin_cover_cover_amount_local_curr
* (p.amount_in_gbp / p.amount_in_txn_currency) as checkin_cover_cover_amount_in_gbp
from int_core__verification_requests vr
left join int_core__bookings b on vr.id_verification_request = b.id_verification_request
left join
stg_core__verification_set_to_verification_type vstvt
on vr.id_verification_set = vstvt.id_verification_set
left join
check_in_cover_payments p on vr.id_verification_request = p.id_verification_request
left join
int_core__check_in_cover_prices ccp on p.currency = ccp.local_currency_iso_4217
-- 15 is Check-in cover.
-- Adding this condition results in only keeping guest journeys that offered the
-- check-in cover
where vstvt.id_verification_type = 15

View file

@ -91,3 +91,36 @@ models:
This could be the check-in date of the booking or the date in which the guest verification
started, depending on the billing settings of the host.
- name: int_core__check_in_cover_prices
description: |
This table shows the active price and cover for the Check-In Hero
product.
The prices are obtained through a gross `GROUP BY` thrown at the payment
validation sets table. It works this way because the price settings of
this product were done with a terrible backend data model design.
How could the prices be changed remains a mystery, and the current design
does not support any kind of history tracking. When the time comes to
adjust prices, we will have a lot of careful work to do to make sure that
we keep history and that no downstream dependencies of this model blow
up.
columns:
- name: local_currency_iso_4217
data_type: character varying
description: A currency code.
- name: checkin_cover_guest_fee_local_curr
data_type: numeric
description: |
The fee that the guest user must pay if he wants to purchase the
cover.
- name: checkin_cover_cover_amount_local_curr
data_type: numeric
description: |
The amount for which the guest user is covered if he faces problems
during check-in.

View file

@ -0,0 +1,35 @@
with core__vr_check_in_cover as (select * from {{ ref("int_core__vr_check_in_cover") }})
select
id_verification_request as id_verification_request,
uuid_verification_request as uuid_verification_request,
id_user_guest as id_user_guest,
id_user_host as id_user_host,
id_booking as id_booking,
id_accommodation as id_accommodation,
is_verification_request_complete as is_verification_request_complete,
is_past_check_in as is_past_check_in,
is_awaiting_check_in as is_awaiting_check_in,
cover_was_purchased as cover_was_purchased,
cover_was_rejected as cover_was_rejected,
guest_email as guest_email,
last_name as last_name,
first_name as first_name,
guest_phone_number as guest_phone_number,
telephone_code as telephone_code,
guest_phone_number_2 as guest_phone_number_2,
check_in_at_utc as check_in_at_utc,
check_in_date_utc as check_in_date_utc,
check_out_at_utc as check_out_at_utc,
check_out_date_utc as check_out_date_utc,
verification_start_at_utc as verification_start_at_utc,
verification_start_date_utc as verification_start_date_utc,
verification_end_at_utc as verification_end_at_utc,
verification_end_date_utc as verification_end_date_utc,
amount_in_txn_currency as amount_in_txn_currency,
currency as currency,
amount_in_gbp as amount_in_gbp,
payment_status as payment_status,
payment_paid_date_utc as payment_paid_date_utc,
checkin_cover_cover_amount_local_curr as checkin_cover_cover_amount_local_curr,
checkin_cover_cover_amount_in_gbp as checkin_cover_cover_amount_in_gbp
from core__vr_check_in_cover

View file

@ -178,3 +178,195 @@ models:
This could be the check-in date of the booking or the date in which the guest verification
started, depending on the billing settings of the host.
- name: core__vr_check_in_cover
description: |
This is a check-in cover specific fact table designed to support basic
reporting on the Check-In Hero product.
Granularity is roughly on the Guest Journey (Verification Request) level.
It contains data from many entities, including Verification Request,
booking, payments, etc.
columns:
- name: id_verification_request
data_type: bigint
description: |
Unique, incremental, internal ID for the related verification
request.
- name: uuid_verification_request
data_type: text
description: uuid for the related verification request.
- name: id_user_guest
data_type: character varying
description: Unique, incremental, internal ID for the guest user.
- name: id_user_host
data_type: character varying
description: Unique, incremental, internal ID for the host user.
- name: id_booking
data_type: bigint
description: Unique, incremental, internal ID for the related booking.
- name: id_accommodation
data_type: bigint
description: Unique, incremental, internal ID for the related listing.
- name: is_verification_request_complete
data_type: boolean
description: |
True if the verification request is considered is considered
complete, AKA the guest has finished the full guest journey.
- name: is_past_check_in
data_type: boolean
description: |
True if the check-in date is in the past, false otherwise. This value
only gets informed for users who have bought check-in cover.
- name: is_awaiting_check_in
data_type: boolean
description: |
True if the check-in date is in the future, false otherwise. This
value only gets informed for users who have bought check-in cover.
- name: cover_was_purchased
data_type: boolean
description: |
True if the guest purchased the check-in cover.
This is identified by the fact that there is a payment of type
check-in cover associated with this guest journey.
- name: cover_was_rejected
data_type: boolean
description: |
True if the guest didn't choose to purchase the check-in cover.
This is identified by the facts:
- There is no payment of type check-in cover associated with this
guest journey.
- The guest journey is completed, meaning the guest can't make the
choice of purchasing the check-in cover anymore.
- name: guest_email
data_type: character varying
description: The email of the guest.
- name: last_name
data_type: character varying
description: The last name of the guest.
- name: first_name
data_type: character varying
description: The first name of the guest.
- name: guest_phone_number
data_type: character varying
description: The phone number of the guest.
- name: telephone_code
data_type: character varying
description: ""
- name: guest_phone_number_2
data_type: character varying
description: ""
- name: check_in_at_utc
data_type: timestamp without time zone
description: The date time when the guest will check-in, in UTC.
- name: check_in_date_utc
data_type: date
description: The date when the guest will check-in, in UTC.
- name: check_out_at_utc
data_type: timestamp without time zone
description: The date time when the guest will check-out, in UTC.
- name: check_out_date_utc
data_type: date
description: The date time when the guest will check-out, in UTC.
- name: verification_start_at_utc
data_type: timestamp without time zone
description: |
The date and time at which the guest started the guest journey.
- name: verification_start_date_utc
data_type: date
description: The date on which the guest started the guest journey.
- name: verification_end_at_utc
data_type: timestamp without time zone
description: |
The date and time at which the guest finished the guest journey.
- name: verification_end_date_utc
data_type: date
description: |
The date at which the guest finished the guest journey.
- name: 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.
- name: currency
data_type: character varying
description: The currency used by the guest for the payment.
- name: amount_in_gbp
data_type: numeric
description: The amount paid by the guest, converted into GBP.
- name: payment_status
data_type: character varying
description: The status of the payment.
- name: payment_paid_date_utc
data_type: date
description: The date in which the guest made the payment.
- name: checkin_cover_cover_amount_local_curr
data_type: numeric
description: |
The total amount for which the guest check-in is covered, according
to the Superhog backend, in the same currency as the guest payment.
Bear in mind that the implementation of Check-In Hero pricing in the
backend holds some tremendous technical debt, which pretty much
prevents changes in the pricing and has no concept of historical
pricing.
The current implementation of this model is very naive and assumes
that prices have not changed. If prices have been changed somehow in
the backend, but someone hasn't taken care of performing the right
updates in upstream dependencies of this model, then it's most
probably broken and unreliable.
For more details, contact pablo.martin or Lawrence.
- name: checkin_cover_cover_amount_in_gbp
data_type: numeric
description: |
The total amount for which the guest check-in is covered, according
to the Superhog backend, converted to GBP.
Bear in mind that the implementation of Check-In Hero pricing in the
backend holds some tremendous technical debt, which pretty much
prevents changes in the pricing and has no concept of historical
pricing.
The current implementation of this model is very naive and assumes
that prices have not changed. If prices have been changed somehow in
the backend, but someone hasn't taken care of performing the right
updates in upstream dependencies of this model, then it's most
probably broken and unreliable.
For more details, contact pablo.martin or Lawrence.

View file

@ -34,3 +34,43 @@ exposures:
owner:
name: Pablo Martin
email: pablo.martin@superhog.com
- name: checkinhero_overview
label: Check-In Hero Overview
type: dashboard
maturity: medium
url: https://app.powerbi.com/Redirect?action=OpenReport&appId=14859ed7-b135-431e-b0a6-229961c10c68&reportObjectId=8e88ea63-1874-47d9-abce-dfcfcea76bda&ctid=862842df-2998-4826-bea9-b726bc01d3a7&reportPage=ReportSectionddc493aece54c925670a&pbi_source=appShareLink&portalSessionId=b5392620-5d7f-4b50-9b21-b8d1867922e7
description: |
A PBI report to monitor the performance of the Check-In Hero product.
Includes contents like Revenue generated, Outstanding Risk being
generated by the product and conversion funnels.
depends_on:
- ref('core__vr_check_in_cover')
- ref('dates')
owner:
name: Pablo Martin
email: pablo.martin@superhog.com
- name: checkinhero_purchase_details
label: Check-In Hero Purchase Details
type: dashboard
maturity: medium
url: https://app.powerbi.com/Redirect?action=OpenReport&appId=14859ed7-b135-431e-b0a6-229961c10c68&reportObjectId=8e88ea63-1874-47d9-abce-dfcfcea76bda&ctid=862842df-2998-4826-bea9-b726bc01d3a7&reportPage=ReportSectionddc493aece54c925670a&pbi_source=appShareLink&portalSessionId=b5392620-5d7f-4b50-9b21-b8d1867922e7
description: |
A PBI report to show the details of the guests and bookings that have
purchased Check-In Hero. The goal is to allow Resolution Agents to
validate if the guest actually purchased the cover when they get claims
related to this product.
depends_on:
- ref('core__vr_check_in_cover')
- ref('dates')
owner:
name: Pablo Martin
email: pablo.martin@superhog.com

View file

@ -171,16 +171,26 @@ sources:
identifier: SuperhogUser
- name: UserVerificationStatus
identifier: UserVerificationStatus
- name: Verification
identifier: Verification
- name: VerificationRequest
identifier: VerificationRequest
- name: VerificationToPayment
identifier: VerificationToPayment
- name: VerificationPaymentType
identifier: VerificationPaymentType
- name: VerificationSetToVerificationType
identifier: VerificationSetToVerificationType
- name: VerificationType
identifier: VerificationType
- name: Payment
identifier: Payment
- name: PaymentStatus
identifier: PaymentStatus
- name: PaymentValidationSet
identifier: PaymentValidationSet
- name: PaymentValidationSetToCurrency
identifier: PaymentValidationSetToCurrency
- name: Booking
identifier: Booking
- name: BookingState

View file

@ -0,0 +1,22 @@
with
raw_payment_validation_set as (
select * from {{ source("core", "PaymentValidationSet") }}
),
stg_core__payment_validation_set as (
select
{{ adapter.quote("Id") }} as id_payment_validation_set,
{{ adapter.quote("SuperhogUserId") }} as id_guest_host,
{{ adapter.quote("Name") }} as payment_validation_set_name,
{{ adapter.quote("Version") }} as payment_validation_set_version,
{{ adapter.quote("IsActive") }} as is_active,
{{ adapter.quote("IsCustom") }} as is_custom,
{{ 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("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_payment_validation_set
)
select *
from stg_core__payment_validation_set

View file

@ -0,0 +1,31 @@
with
raw_payment_validation_set_to_currency as (
select * from {{ source("core", "PaymentValidationSetToCurrency") }}
),
stg_core__payment_validation_set_to_currency as (
select
{{ adapter.quote("Id") }} as id_payment_validation_set_to_currency,
{{ adapter.quote("PaymentValidationSetId") }} as id_payment_validation_set,
{{ adapter.quote("Fee") }} as guest_fee_local_curr,
{{ adapter.quote("Amount") }} as deposit_amount_local_curr,
{{ adapter.quote("Waiver") }} as waiver_guest_fee_amount_local_curr,
{{ adapter.quote("Protection") }} as waiver_protection_amount_local_curr,
{{ adapter.quote("CancellationCoverCostA") }} -- this field will need a rename when checkincover gets deployed in production
as checkin_cover_guest_fee_local_curr,
{{ adapter.quote("CancellationCoverLimitA") }} -- this field will need a rename when checkincover gets deployed in production
as checkin_cover_cover_amount_local_curr,
{{ adapter.quote("Reschedule") }} as reschedule,
{{ adapter.quote("CurrencyIso") }} as local_currency_iso_4217,
{{ adapter.quote("IsFeeRefundable") }} as is_fee_refundable,
{{ adapter.quote("DisabledValidationOptions") }}
as disabled_validation_options,
{{ 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("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_payment_validation_set_to_currency
)
select *
from stg_core__payment_validation_set_to_currency

View file

@ -0,0 +1,24 @@
with
raw_verification as (select * from {{ source("core", "Verification") }}),
stg_core__verification as (
select
{{ adapter.quote("Id") }} as id_verification,
{{ adapter.quote("SuperhogUserId") }} as id_user_guest,
{{ adapter.quote("VerificationStatusId") }} as id_verification_status,
{{ adapter.quote("VerificationRequestId") }} as id_verification_request,
{{ adapter.quote("Name") }} as verification,
{{ adapter.quote("Value") }} as verification_value,
{{ adapter.quote("MetaData") }} as metadata,
{{ adapter.quote("Provider") }} as verification_provider,
{{ 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 update_date_utc,
{{ adapter.quote("DeletedDate") }} as deleted_at_utc,
cast({{ adapter.quote("DeletedDate") }} as date) as deleted_date_utc,
{{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_verification
)
select *
from stg_core__verification

View file

@ -0,0 +1,23 @@
with
raw_verificationsettoverificationtype as (
select * from {{ source("core", "VerificationSetToVerificationType") }}
),
stg_core__verification_set_to_verification_type as (
select
{{ adapter.quote("Id") }} as id_verification_set_to_verification_type,
{{ adapter.quote("VerificationSetId") }} as id_verification_set,
{{ adapter.quote("VerificationTypeId") }} as id_verification_type,
{{ adapter.quote("Rules") }} as rules,
{{ adapter.quote("Hidden") }} as is_hidden,
{{ adapter.quote("MetaData") }} as metadata,
{{ adapter.quote("SortOrder") }} as sort_order,
{{ 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("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_verificationsettoverificationtype
)
select *
from stg_core__verification_set_to_verification_type

View file

@ -0,0 +1,18 @@
with
raw_verification_type as (select * from {{ source("core", "VerificationType") }}),
stg_core__verification_type as (
select
{{ adapter.quote("Id") }} as id_verification_type,
{{ adapter.quote("Name") }} as verification_type,
{{ adapter.quote("Provider") }} as verification_provider,
{{ adapter.quote("IncludedInUserInterface") }},
{{ 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("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_verification_type
)
select *
from stg_core__verification_type