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,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