fixed join for billing_countries and created new model for timeframe aggregations
This commit is contained in:
parent
7717ce3c53
commit
de2cb8264b
2 changed files with 155 additions and 7 deletions
144
models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql
Normal file
144
models/intermediate/kpis/int_kpis__product_guest_agg_metrics.sql
Normal file
|
|
@ -0,0 +1,144 @@
|
||||||
|
{% set yesterday = "(current_date - interval '1 day')" %}
|
||||||
|
{% set metric_names = (
|
||||||
|
"created_guest_journeys_not_cancelled",
|
||||||
|
"started_guest_journeys_not_cancelled",
|
||||||
|
"completed_guest_journeys_not_cancelled",
|
||||||
|
"created_guest_journeys",
|
||||||
|
"started_guest_journeys",
|
||||||
|
"completed_guest_journeys",
|
||||||
|
"total_csat_score_count",
|
||||||
|
"average_csat_score",
|
||||||
|
"deposit_fees_in_gbp",
|
||||||
|
"waiver_payments_in_gbp",
|
||||||
|
"checkin_cover_fees_in_gbp",
|
||||||
|
"total_guest_payments_in_gbp",
|
||||||
|
) %}
|
||||||
|
|
||||||
|
with
|
||||||
|
int_kpis__product_guest_daily_metrics as (
|
||||||
|
select
|
||||||
|
date_day,
|
||||||
|
has_payment,
|
||||||
|
has_id_check,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
{% for metric in metric_names %}
|
||||||
|
{{ metric }}{% if not loop.last %},{% endif %}
|
||||||
|
{% endfor %}
|
||||||
|
from {{ ref("int_kpis__product_guest_daily_metrics") }}
|
||||||
|
),
|
||||||
|
date_ranges as (
|
||||||
|
select
|
||||||
|
{{ yesterday }} as current_date,
|
||||||
|
date_trunc('month', {{ yesterday }}) as current_month_start,
|
||||||
|
date_trunc('week', {{ yesterday }}) as current_week_start, -- Start of the current week
|
||||||
|
date_trunc('week', {{ yesterday }} - interval '1 year') as py_week_start, -- Start of the same week last year
|
||||||
|
date_trunc('week', {{ yesterday }} - interval '1 year')
|
||||||
|
+ interval '1 day'
|
||||||
|
* extract(
|
||||||
|
dow from {{ yesterday }} - interval '1 day'
|
||||||
|
) as py_week_current_date,
|
||||||
|
date_trunc('week', {{ yesterday }} - interval '1 week') as pp_week_start, -- Start of the same week in the previous period
|
||||||
|
date_trunc('month', {{ yesterday }} - interval '1 year') as py_month_start,
|
||||||
|
date_trunc('year', {{ yesterday }}) as current_year_start,
|
||||||
|
date_trunc('year', {{ yesterday }} - interval '1 year') as py_year_start,
|
||||||
|
date_trunc('month', {{ yesterday }} - interval '1 month') as pp_month_start,
|
||||||
|
{{ yesterday }} - interval '1 year' as py_current_date,
|
||||||
|
{{ yesterday }} - interval '1 month' as pm_current_date,
|
||||||
|
{{ yesterday }} - interval '1 week' as pw_current_date,
|
||||||
|
extract(day from {{ yesterday }}) as current_day_of_month
|
||||||
|
|
||||||
|
),
|
||||||
|
aggregated_metrics as (
|
||||||
|
{% for metric in metric_names %}
|
||||||
|
select
|
||||||
|
'{{ metric }}' as metric,
|
||||||
|
has_payment,
|
||||||
|
has_id_check,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
'YTD' as timeframe,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.current_year_start and {{ yesterday }}
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as current_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.py_year_start and dr.py_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as py_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.py_year_start and dr.py_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as pp_value
|
||||||
|
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||||
|
where extract(day from date_day) <= dr.current_day_of_month
|
||||||
|
group by
|
||||||
|
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||||
|
union all
|
||||||
|
select
|
||||||
|
'{{ metric }}' as metric,
|
||||||
|
has_payment,
|
||||||
|
has_id_check,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
'MTD' as timeframe,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.current_month_start and {{ yesterday }}
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as current_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.py_month_start and dr.py_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as py_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.pp_month_start and dr.pm_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as pp_value
|
||||||
|
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||||
|
where extract(day from date_day) <= dr.current_day_of_month
|
||||||
|
group by
|
||||||
|
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||||
|
union all
|
||||||
|
select
|
||||||
|
'{{ metric }}' as metric,
|
||||||
|
has_payment,
|
||||||
|
has_id_check,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
'WTD' as timeframe,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.current_week_start and {{ yesterday }}
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as current_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.py_week_start and py_week_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as py_value,
|
||||||
|
sum(
|
||||||
|
case
|
||||||
|
when date_day between dr.pp_week_start and dr.pw_current_date
|
||||||
|
then dm.{{ metric }}
|
||||||
|
end
|
||||||
|
) as pp_value
|
||||||
|
from int_kpis__product_guest_daily_metrics dm, date_ranges dr
|
||||||
|
group by
|
||||||
|
metric, has_payment, has_id_check, main_billing_country_iso_3_per_deal
|
||||||
|
{% if not loop.last %}
|
||||||
|
union all
|
||||||
|
{% endif %}
|
||||||
|
{% endfor %}
|
||||||
|
)
|
||||||
|
select *
|
||||||
|
from aggregated_metrics
|
||||||
|
|
@ -1,5 +1,3 @@
|
||||||
{% set has_payment_true = "('With Payment')" %}
|
|
||||||
|
|
||||||
with
|
with
|
||||||
guest_journey_metrics as (
|
guest_journey_metrics as (
|
||||||
select
|
select
|
||||||
|
|
@ -27,7 +25,8 @@ with
|
||||||
/ sum(gj.count_csat_score)
|
/ sum(gj.count_csat_score)
|
||||||
else null
|
else null
|
||||||
end as average_csat_score
|
end as average_csat_score
|
||||||
from {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} gj
|
from
|
||||||
|
"intermediate"."int_kpis__metric_daily_check_in_attributed_guest_journeys" gj
|
||||||
group by
|
group by
|
||||||
gj.date,
|
gj.date,
|
||||||
gj.has_payment,
|
gj.has_payment,
|
||||||
|
|
@ -43,7 +42,7 @@ with
|
||||||
sum(gp.waiver_payments_in_gbp) as waiver_payments_in_gbp,
|
sum(gp.waiver_payments_in_gbp) as waiver_payments_in_gbp,
|
||||||
sum(gp.checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp,
|
sum(gp.checkin_cover_fees_in_gbp) as checkin_cover_fees_in_gbp,
|
||||||
sum(gp.total_guest_payments_in_gbp) as total_guest_payments_in_gbp
|
sum(gp.total_guest_payments_in_gbp) as total_guest_payments_in_gbp
|
||||||
from {{ ref("int_kpis__metric_daily_guest_payments") }} gp
|
from "intermediate"."int_kpis__metric_daily_guest_payments" gp
|
||||||
where gp.date < current_date
|
where gp.date < current_date
|
||||||
group by gp.date, gp.has_id_check, gp.main_billing_country_iso_3_per_deal
|
group by gp.date, gp.has_id_check, gp.main_billing_country_iso_3_per_deal
|
||||||
),
|
),
|
||||||
|
|
@ -66,22 +65,25 @@ with
|
||||||
gp.waiver_payments_in_gbp,
|
gp.waiver_payments_in_gbp,
|
||||||
gp.checkin_cover_fees_in_gbp,
|
gp.checkin_cover_fees_in_gbp,
|
||||||
gp.total_guest_payments_in_gbp
|
gp.total_guest_payments_in_gbp
|
||||||
from {{ ref("int_kpis__dimension_date_product_guest") }} dd
|
from "intermediate"."int_kpis__dimension_date_product_guest" dd
|
||||||
left join
|
left join
|
||||||
guest_journey_metrics gj
|
guest_journey_metrics gj
|
||||||
on gj.date = dd.date_day
|
on gj.date = dd.date_day
|
||||||
and gj.has_payment = dd.has_payment
|
and gj.has_payment = dd.has_payment
|
||||||
and gj.has_id_check = dd.has_id_check
|
and gj.has_id_check = dd.has_id_check
|
||||||
|
and gj.main_billing_country_iso_3_per_deal
|
||||||
|
= dd.main_billing_country_iso_3_per_deal
|
||||||
left join
|
left join
|
||||||
guest_payment_metrics gp
|
guest_payment_metrics gp
|
||||||
on gp.date = dd.date_day
|
on gp.date = dd.date_day
|
||||||
and gp.has_id_check = dd.has_id_check
|
and gp.has_id_check = dd.has_id_check
|
||||||
and dd.has_payment = {{ has_payment_true }}
|
and dd.has_payment = ('With Payment')
|
||||||
|
and gp.main_billing_country_iso_3_per_deal
|
||||||
|
= dd.main_billing_country_iso_3_per_deal
|
||||||
-- Restricts the records by date being in the past or in the next following 12
|
-- Restricts the records by date being in the past or in the next following 12
|
||||||
-- months
|
-- months
|
||||||
where dd.date_day <= current_date + interval '1 year'
|
where dd.date_day <= current_date + interval '1 year'
|
||||||
)
|
)
|
||||||
|
|
||||||
select
|
select
|
||||||
gk.date_day,
|
gk.date_day,
|
||||||
gk.date_week,
|
gk.date_week,
|
||||||
|
|
@ -141,6 +143,8 @@ left join
|
||||||
on gk.date_day = gk_py.date_day + interval '1 year'
|
on gk.date_day = gk_py.date_day + interval '1 year'
|
||||||
and gk.has_payment = gk_py.has_payment
|
and gk.has_payment = gk_py.has_payment
|
||||||
and gk.has_id_check = gk_py.has_id_check
|
and gk.has_id_check = gk_py.has_id_check
|
||||||
|
and gk.main_billing_country_iso_3_per_deal
|
||||||
|
= gk_py.main_billing_country_iso_3_per_deal
|
||||||
-- Here we use a group by because of leap days that generate duplicity when being
|
-- Here we use a group by because of leap days that generate duplicity when being
|
||||||
-- moved to another year
|
-- moved to another year
|
||||||
group by
|
group by
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue