Merged PR 3385: Adds Guest Journey with Payment metric

# Description

Adds GJ with Payment. It includes:
* Daily model
* Monthly/MTD without dimension aggregates
* Monthly/MTD with dimension aggregates
* Schema entries for the abovementioned 5 models
* Temporary test to compare against current production KPIs

# 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: #23453
This commit is contained in:
Oriol Roqué Paniagua 2024-10-30 16:43:50 +00:00
parent 0aac0fcb61
commit 9585b759a4
7 changed files with 499 additions and 0 deletions

View file

@ -0,0 +1,24 @@
{% set dimensions = get_kpi_dimensions_per_model("GUEST_JOURNEYS_WITH_PAYMENT") %}
{{
config(
materialized="table", unique_key=["end_date", "dimension", "dimension_value"]
)
}}
{% for dimension in dimensions %}
select
-- Unique Key --
start_date,
end_date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
-- Metrics --
sum(guest_journeys_with_payment) as guest_journeys_with_payment
from {{ ref("int_kpis__metric_monthly_guest_journeys_with_payment") }}
group by 1, 2, 3, 4
{% if not loop.last %}
union all
{% endif %}
{% endfor %}

View file

@ -0,0 +1,24 @@
{% set dimensions = get_kpi_dimensions_per_model("GUEST_JOURNEYS_WITH_PAYMENT") %}
{{
config(
materialized="table", unique_key=["end_date", "dimension", "dimension_value"]
)
}}
{% for dimension in dimensions %}
select
-- Unique Key --
start_date,
end_date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
-- Metrics --
sum(guest_journeys_with_payment) as guest_journeys_with_payment
from {{ ref("int_kpis__metric_mtd_guest_journeys_with_payment") }}
group by 1, 2, 3, 4
{% if not loop.last %}
union all
{% endif %}
{% endfor %}

View file

@ -0,0 +1,37 @@
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
first_payment_per_verification_request as (
select
vp.id_verification_request,
min(vp.payment_paid_date_utc) as first_payment_paid_date_utc
from {{ ref("int_core__verification_payments", version=2) }} vp
where
upper(vp.payment_status) = {{ var("paid_payment_state") }}
and vp.id_verification_request is not null
group by 1
)
select
-- Unique Key --
p.first_payment_paid_date_utc as date,
coalesce(icuh.id_deal, 'UNSET') as id_deal,
-- Dimensions --
coalesce(
icd.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
coalesce(
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
) as active_accommodations_per_deal_segmentation,
-- Metrics --
count(distinct icvr.id_verification_request) as guest_journeys_with_payment
from first_payment_per_verification_request as p
left join
{{ ref("int_core__verification_requests") }} as icvr
on p.id_verification_request = icvr.id_verification_request
left join
{{ ref("int_core__user_host") }} as icuh on icvr.id_user_host = icuh.id_user_host
left join {{ ref("int_core__deal") }} as icd on icuh.id_deal = icd.id_deal
left join
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
on icuh.id_deal = icmas.id_deal
and p.first_payment_paid_date_utc = icmas.date
group by 1, 2, 3, 4

View file

@ -0,0 +1,27 @@
{{
config(
materialized="view",
unique_key=[
"end_date",
"id_deal",
"active_accommodations_per_deal_segmentation",
],
)
}}
select
-- Unique Key --
d.first_day_month as start_date,
d.date as end_date,
gj.id_deal,
gj.active_accommodations_per_deal_segmentation,
-- Dimensions --
gj.main_billing_country_iso_3_per_deal,
-- Metrics --
sum(gj.guest_journeys_with_payment) as guest_journeys_with_payment
from {{ ref("int_kpis__dimension_dates") }} d
left join
{{ ref("int_kpis__metric_daily_guest_journeys_with_payment") }} gj
on date_trunc('month', gj.date)::date = d.first_day_month
where d.is_end_of_month = true and gj.id_deal is not null
group by 1, 2, 3, 4, 5

View file

@ -0,0 +1,28 @@
{{
config(
materialized="view",
unique_key=[
"end_date",
"id_deal",
"active_accommodations_per_deal_segmentation",
],
)
}}
select
-- Unique Key --
d.first_day_month as start_date,
d.date as end_date,
gj.id_deal,
gj.active_accommodations_per_deal_segmentation,
-- Dimensions --
gj.main_billing_country_iso_3_per_deal,
-- Metrics --
sum(gj.guest_journeys_with_payment) as guest_journeys_with_payment
from {{ ref("int_kpis__dimension_dates") }} d
left join
{{ ref("int_kpis__metric_daily_guest_journeys_with_payment") }} gj
on date_trunc('month', gj.date)::date = d.first_day_month
and extract(day from gj.date) <= d.day
where d.is_month_to_date = true and gj.id_deal is not null
group by 1, 2, 3, 4, 5

View file

@ -1458,3 +1458,305 @@ models:
- name: completed_guest_journeys
data_type: bigint
description: The month-to-date completed guest journeys for a given date, dimension and value.
- name: int_kpis__metric_daily_guest_journeys_with_payment
description: |
This model computes the Daily Guest Journeys with Payment at the deepest granularity.
The unique key corresponds to the deepest granularity of the model,
in this case:
- date,
- id_deal.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
columns:
- name: date
data_type: date
description: Date of when Guest Journeys have been completed.
tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
tests:
- not_null
- name: active_accommodations_per_deal_segmentation
data_type: string
description: |
Segment value based on the number of listings booked in 12 months
for a given deal and date.
tests:
- not_null
- accepted_values:
values:
- "0"
- "01-05"
- "06-20"
- "21-60"
- "61+"
- "UNSET"
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
Main billing country of the host aggregated at Deal level.
tests:
- not_null
- name: guest_journeys_with_payment
data_type: bigint
description: |
Count of daily guest journeys completed in a given date and per specified dimension.
- name: int_kpis__metric_monthly_guest_journeys_with_payment
description: |
This model computes the Monthly Guest Journeys with Payment at the
deepest granularity.
Be aware that any dimension that can change over the monthly period,
such as daily segmentations, are included in the primary key of the
model.
The unique key corresponds to:
- end_date,
- id_deal,
- active_accommodations_per_deal_segmentation.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- id_deal
- active_accommodations_per_deal_segmentation
columns:
- name: start_date
data_type: date
description: |
The start date of the time range considered for the metrics in this record.
tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
tests:
- not_null
- name: active_accommodations_per_deal_segmentation
data_type: string
description: |
Segment value based on the number of listings booked in 12 months
for a given deal and date.
tests:
- not_null
- accepted_values:
values:
- "0"
- "01-05"
- "06-20"
- "21-60"
- "61+"
- "UNSET"
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
Main billing country of the host aggregated at Deal level.
tests:
- not_null
- name: guest_journeys_with_payment
data_type: bigint
description: |
Count of accummulated guest journeys completed in a given month
and per specified dimension.
- name: int_kpis__metric_mtd_guest_journeys_with_payment
description: |
This model computes the Month-To-Date Guest Journeys with Payment at the
deepest granularity.
Be aware that any dimension that can change over the monthly period,
such as daily segmentations, are included in the primary key of the
model.
The unique key corresponds to:
- end_date,
- id_deal,
- active_accommodations_per_deal_segmentation.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- id_deal
- active_accommodations_per_deal_segmentation
columns:
- name: start_date
data_type: date
description: |
The start date of the time range considered for the metrics in this record.
tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
tests:
- not_null
- name: active_accommodations_per_deal_segmentation
data_type: string
description: |
Segment value based on the number of listings booked in 12 months
for a given deal and date.
tests:
- not_null
- accepted_values:
values:
- "0"
- "01-05"
- "06-20"
- "21-60"
- "61+"
- "UNSET"
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
Main billing country of the host aggregated at Deal level.
tests:
- not_null
- name: guest_journeys_with_payment
data_type: bigint
description: |
Count of accummulated guest journeys completed in a given month up to the
given date and per specified dimension.
- name: int_kpis__aggregated_monthly_guest_journeys_with_payment
description: |
This model computes the dimension aggregation for
Monthly Guest Journeys with Payment.
The primary key of this model is end_date, dimension
and dimension_value.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- dimension
- dimension_value
columns:
- name: start_date
data_type: date
description: |
The start date of the time range considered for the metrics in this record.
tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
tests:
- not_null
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
tests:
- assert_dimension_completeness:
metric_column_name: guest_journeys_with_payment
- accepted_values:
values:
- global
- by_number_of_listings
- by_billing_country
- by_deal
- name: dimension_value
data_type: string
description: The value or segment available for the selected dimension.
tests:
- not_null
- name: guest_journeys_with_payment
data_type: bigint
description: The monthly guest journeys with payment for a given date, dimension and value.
- name: int_kpis__aggregated_mtd_guest_journeys_with_payment
description: |
This model computes the dimension aggregation for
Month-To-Date Guest Journeys with Payment.
The primary key of this model is end_date, dimension
and dimension_value.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- dimension
- dimension_value
columns:
- name: start_date
data_type: date
description: |
The start date of the time range considered for the metrics in this record.
tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
tests:
- not_null
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
tests:
- assert_dimension_completeness:
metric_column_name: guest_journeys_with_payment
- accepted_values:
values:
- global
- by_number_of_listings
- by_billing_country
- by_deal
- name: dimension_value
data_type: string
description: The value or segment available for the selected dimension.
tests:
- not_null
- name: guest_journeys_with_payment
data_type: bigint
description: The month-to-date guest journeys with payment for a given date, dimension and value.

View file

@ -0,0 +1,57 @@
{% set min_date = "2022-01-01" %}
{% set dimensions = ("global", "by_billing_country") %}
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
-- segmentation
with
new_mtd_guest_journeys_with_payment as (
select end_date as date, dimension, dimension_value, guest_journeys_with_payment
from {{ ref("int_kpis__aggregated_mtd_guest_journeys_with_payment") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_monthly_guest_journeys_with_payment as (
select end_date as date, dimension, dimension_value, guest_journeys_with_payment
from {{ ref("int_kpis__aggregated_monthly_guest_journeys_with_payment") }}
where
end_date >= '{{ min_date }}'
and dimension in {{ dimensions }}
and dimension_value <> 'UNSET'
),
new_guest_journeys_with_payment as (
select *
from new_mtd_guest_journeys_with_payment
union all
select *
from new_monthly_guest_journeys_with_payment
),
old_guest_journeys_with_payment as (
select
date,
dimension,
dimension_value,
paid_guest_journeys as guest_journeys_with_payment
from {{ ref("int_core__mtd_guest_journey_metrics") }}
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
),
comparison as (
select
coalesce(o.date, n.date) as date,
coalesce(o.dimension, n.dimension) as dimension,
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
o.guest_journeys_with_payment as old_guest_journeys_with_payment,
n.guest_journeys_with_payment as new_guest_journeys_with_payment,
coalesce(o.guest_journeys_with_payment, 0)
- coalesce(n.guest_journeys_with_payment, 0) as diff
from old_guest_journeys_with_payment o
full outer join
new_guest_journeys_with_payment n
on o.date = n.date
and o.dimension = n.dimension
and o.dimension_value = n.dimension_value
)
select *
from comparison
where diff <> 0
order by date desc, abs(diff) desc