Merged PR 3769: Adds int_core__ab_test_monitoring_guest_journey
# Description Adds a table that contain the main information needed for metric computation at verification request level that is part of an A/B test. # 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. - [NA] 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: #25146
This commit is contained in:
parent
37c508fa69
commit
616b949ba4
2 changed files with 206 additions and 0 deletions
|
|
@ -0,0 +1,110 @@
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="table", unique_key=["id_verification_request", "ab_test_name"]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
{% set deposit_fees_verification_payment_type_items = "('FEE')" %}
|
||||||
|
{% set waiver_fees_verification_payment_type_items = "('WAIVER')" %}
|
||||||
|
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
|
||||||
|
with
|
||||||
|
int_core__ab_test_tracking_guest_journey as (
|
||||||
|
select * from {{ ref("int_core__ab_test_tracking_guest_journey") }}
|
||||||
|
),
|
||||||
|
int_core__verification_payments as (
|
||||||
|
select * from {{ ref("int_core__verification_payments", version=2) }}
|
||||||
|
),
|
||||||
|
int_core__verification_requests as (
|
||||||
|
select * from {{ ref("int_core__verification_requests") }}
|
||||||
|
),
|
||||||
|
int_core__guest_satisfaction_responses as (
|
||||||
|
select * from {{ ref("int_core__guest_satisfaction_responses") }}
|
||||||
|
),
|
||||||
|
ab_test_tracking as (
|
||||||
|
select
|
||||||
|
id_verification_request,
|
||||||
|
ab_test_name,
|
||||||
|
variation,
|
||||||
|
date(first_appearance_at_utc) as first_appearance_date_utc
|
||||||
|
from int_core__ab_test_tracking_guest_journey
|
||||||
|
),
|
||||||
|
guest_journey_data as (
|
||||||
|
select
|
||||||
|
abt.ab_test_name,
|
||||||
|
abt.variation,
|
||||||
|
abt.id_verification_request,
|
||||||
|
abt.first_appearance_date_utc,
|
||||||
|
vr.verification_estimated_started_date_utc as verification_started_date_utc,
|
||||||
|
vr.verification_estimated_completed_date_utc
|
||||||
|
as verification_completed_date_utc,
|
||||||
|
gsr.experience_rating
|
||||||
|
from ab_test_tracking abt
|
||||||
|
left join
|
||||||
|
int_core__verification_requests vr
|
||||||
|
on abt.id_verification_request = vr.id_verification_request
|
||||||
|
left join
|
||||||
|
int_core__guest_satisfaction_responses gsr
|
||||||
|
on abt.id_verification_request = gsr.id_verification_request
|
||||||
|
)
|
||||||
|
select
|
||||||
|
gjd.ab_test_name,
|
||||||
|
gjd.variation,
|
||||||
|
gjd.id_verification_request,
|
||||||
|
gjd.first_appearance_date_utc,
|
||||||
|
gjd.verification_started_date_utc,
|
||||||
|
gjd.verification_completed_date_utc,
|
||||||
|
gjd.experience_rating,
|
||||||
|
max(vp.payment_paid_date_utc) as last_payment_paid_date_utc,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when
|
||||||
|
upper(vp.verification_payment_type)
|
||||||
|
in {{ deposit_fees_verification_payment_type_items }}
|
||||||
|
or upper(vp.verification_payment_type)
|
||||||
|
in {{ waiver_fees_verification_payment_type_items }}
|
||||||
|
or upper(vp.verification_payment_type)
|
||||||
|
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||||
|
then amount_without_taxes_in_gbp
|
||||||
|
else null
|
||||||
|
end
|
||||||
|
) as guest_revenue_without_taxes_in_gbp,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when
|
||||||
|
upper(vp.verification_payment_type)
|
||||||
|
in {{ deposit_fees_verification_payment_type_items }}
|
||||||
|
then amount_without_taxes_in_gbp
|
||||||
|
else null
|
||||||
|
end
|
||||||
|
) as deposit_fees_without_taxes_in_gbp,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when
|
||||||
|
upper(vp.verification_payment_type)
|
||||||
|
in {{ waiver_fees_verification_payment_type_items }}
|
||||||
|
then amount_without_taxes_in_gbp
|
||||||
|
else null
|
||||||
|
end
|
||||||
|
) as waiver_fees_without_taxes_in_gbp,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when
|
||||||
|
upper(vp.verification_payment_type)
|
||||||
|
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||||
|
then amount_without_taxes_in_gbp
|
||||||
|
else null
|
||||||
|
end
|
||||||
|
) as check_in_cover_fees_without_taxes_in_gbp
|
||||||
|
from guest_journey_data gjd
|
||||||
|
left join
|
||||||
|
int_core__verification_payments vp
|
||||||
|
on gjd.id_verification_request = vp.id_verification_request
|
||||||
|
and upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||||
|
and (
|
||||||
|
upper(vp.verification_payment_type)
|
||||||
|
in {{ deposit_fees_verification_payment_type_items }}
|
||||||
|
or upper(vp.verification_payment_type)
|
||||||
|
in {{ waiver_fees_verification_payment_type_items }}
|
||||||
|
or upper(vp.verification_payment_type)
|
||||||
|
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||||
|
)
|
||||||
|
group by 1, 2, 3, 4, 5, 6, 7
|
||||||
|
|
@ -4333,3 +4333,99 @@ models:
|
||||||
purposes. Cannot be null.
|
purposes. Cannot be null.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: int_core__ab_test_monitoring_guest_journey
|
||||||
|
description: |
|
||||||
|
Provides the Guest Journey A/B test key information to build metric monitoring on top.
|
||||||
|
|
||||||
|
The purpose of this table is not to compute the metrics themselves, but rather leave
|
||||||
|
a bit of open possibilities for whenever we're analysing results later on. This is
|
||||||
|
already materialised to avoid running long queries in the notebooks.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- id_verification_request
|
||||||
|
- ab_test_name
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: id_verification_request
|
||||||
|
data_type: integer
|
||||||
|
description: |
|
||||||
|
Identifier of the Verification Request. Acts as foreign key to the Verification Request table.
|
||||||
|
It can be duplicated across different Feature Flags - meaning the same verification request
|
||||||
|
can be part of none, one, or several A/B tests.
|
||||||
|
In this table, a Verification Request or Guest Journey can only appear once per A/B test.
|
||||||
|
Cannot be null.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: ab_test_name
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Name of the Guest Journey A/B test. It corresponds to the Feature Flag Name in the
|
||||||
|
backend. Cannot be null.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: variation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Identifier of the variation a given Verification Request is in, within a
|
||||||
|
given Guest Journey A/B test. Cannot be null.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: first_appearance_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of the first Verification Request Feature Flag record created
|
||||||
|
with the same verification request and A/B test name. Mostly for information
|
||||||
|
purposes. Cannot be null.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: verification_started_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of when the Guest Journey was started. Can be null.
|
||||||
|
|
||||||
|
- name: verification_completed_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of when the Guest Journey was completed. Can be null.
|
||||||
|
|
||||||
|
- name: experience_rating
|
||||||
|
data_type: integer
|
||||||
|
description: |
|
||||||
|
CSAT score value for the Guest Journey. Can be null.
|
||||||
|
|
||||||
|
- name: last_payment_paid_date_utc
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
Date of when the last paid payment on this Guest Journey
|
||||||
|
happened. Can be null.
|
||||||
|
|
||||||
|
- name: guest_revenue_without_taxes_in_gbp
|
||||||
|
data_type: float
|
||||||
|
description: |
|
||||||
|
Total guest revenue paid without taxes in GBP, including Deposit
|
||||||
|
Fees, Waiver Fees and Check-In Cover fees. Can be null.
|
||||||
|
|
||||||
|
- name: deposit_fees_without_taxes_in_gbp
|
||||||
|
data_type: float
|
||||||
|
description: |
|
||||||
|
Deposit fees revenue paid without taxes in GBP.
|
||||||
|
Can be null.
|
||||||
|
|
||||||
|
- name: waiver_fees_without_taxes_in_gbp
|
||||||
|
data_type: float
|
||||||
|
description: |
|
||||||
|
Waiver fees revenue paid without taxes in GBP.
|
||||||
|
Can be null.
|
||||||
|
|
||||||
|
- name: check_in_cover_fees_without_taxes_in_gbp
|
||||||
|
data_type: float
|
||||||
|
description: |
|
||||||
|
Check-in Cover fees revenue paid without taxes in GBP.
|
||||||
|
Can be null.
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue