Merged PR 3377: Adds GJ Created, Started and Completed in new KPIs flow
# Description Adds GJ Created, Started and Completed. Each model has: * A Daily model * A Monthly/MTD without dimension aggregate * A Monthly/MTD with dimension aggregate * A comparison vs. the current flow of KPIs in the form of a test It's quite similar as for Created Bookings. The main difference is that 1) reads from Verification Requests table and 2) I don't compute a New Dash dimension. This helps actually validating the logic of the dimension configuration macro, which works good. I confirm that the 3 tests of comparison vs. current data work well in my local - i.e. identical content for Global, Billing Country for these 3 metrics since 2022. This does not include: * Guest Journeys with Payment. I'll do this in a separated PR * Guest Payments/Revenue. I'll do this in a separated PR # 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. **Briefly discussed with Pablo, we'll leave it like this for the time being** - [X] I've picked the right materialization for the affected models. **Runs quite fast** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #23453
This commit is contained in:
parent
86719b6a10
commit
8ddb695947
19 changed files with 1446 additions and 3 deletions
|
|
@ -0,0 +1,53 @@
|
|||
{% 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_completed_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, completed_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_mtd_completed_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_monthly_completed_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, completed_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_monthly_completed_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_completed_guest_journeys as (
|
||||
select *
|
||||
from new_mtd_completed_guest_journeys
|
||||
union all
|
||||
select *
|
||||
from new_monthly_completed_guest_journeys
|
||||
),
|
||||
old_completed_guest_journeys as (
|
||||
select date, dimension, dimension_value, completed_guest_journeys
|
||||
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.completed_guest_journeys as old_completed_guest_journeys,
|
||||
n.completed_guest_journeys as new_completed_guest_journeys,
|
||||
coalesce(o.completed_guest_journeys, 0)
|
||||
- coalesce(n.completed_guest_journeys, 0) as diff
|
||||
from old_completed_guest_journeys o
|
||||
full outer join
|
||||
new_completed_guest_journeys 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
|
||||
|
|
@ -0,0 +1,53 @@
|
|||
{% 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_created_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, created_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_mtd_created_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_monthly_created_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, created_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_monthly_created_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_created_guest_journeys as (
|
||||
select *
|
||||
from new_mtd_created_guest_journeys
|
||||
union all
|
||||
select *
|
||||
from new_monthly_created_guest_journeys
|
||||
),
|
||||
old_created_guest_journeys as (
|
||||
select date, dimension, dimension_value, created_guest_journeys
|
||||
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.created_guest_journeys as old_created_guest_journeys,
|
||||
n.created_guest_journeys as new_created_guest_journeys,
|
||||
coalesce(o.created_guest_journeys, 0)
|
||||
- coalesce(n.created_guest_journeys, 0) as diff
|
||||
from old_created_guest_journeys o
|
||||
full outer join
|
||||
new_created_guest_journeys 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
|
||||
|
|
@ -0,0 +1,53 @@
|
|||
{% 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_started_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, started_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_mtd_started_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_monthly_started_guest_journeys as (
|
||||
select end_date as date, dimension, dimension_value, started_guest_journeys
|
||||
from {{ ref("int_kpis__aggregated_monthly_started_guest_journeys") }}
|
||||
where
|
||||
end_date >= '{{ min_date }}'
|
||||
and dimension in {{ dimensions }}
|
||||
and dimension_value <> 'UNSET'
|
||||
),
|
||||
new_started_guest_journeys as (
|
||||
select *
|
||||
from new_mtd_started_guest_journeys
|
||||
union all
|
||||
select *
|
||||
from new_monthly_started_guest_journeys
|
||||
),
|
||||
old_started_guest_journeys as (
|
||||
select date, dimension, dimension_value, started_guest_journeys
|
||||
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.started_guest_journeys as old_started_guest_journeys,
|
||||
n.started_guest_journeys as new_started_guest_journeys,
|
||||
coalesce(o.started_guest_journeys, 0)
|
||||
- coalesce(n.started_guest_journeys, 0) as diff
|
||||
from old_started_guest_journeys o
|
||||
full outer join
|
||||
new_started_guest_journeys 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
|
||||
Loading…
Add table
Add a link
Reference in a new issue