78 lines
2.5 KiB
MySQL
78 lines
2.5 KiB
MySQL
|
|
{% 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",
|
||
|
|
"py_created_guest_journeys_not_cancelled",
|
||
|
|
"py_started_guest_journeys_not_cancelled",
|
||
|
|
"py_completed_guest_journeys_not_cancelled",
|
||
|
|
"py_created_guest_journeys",
|
||
|
|
"py_started_guest_journeys",
|
||
|
|
"py_completed_guest_journeys",
|
||
|
|
"py_total_csat_score_count",
|
||
|
|
"py_average_csat_score",
|
||
|
|
"py_deposit_fees_in_gbp",
|
||
|
|
"py_waiver_payments_in_gbp",
|
||
|
|
"py_checkin_cover_fees_in_gbp",
|
||
|
|
"py_total_guest_payments_in_gbp",
|
||
|
|
) %}
|
||
|
|
{% set sigma_threshold = var("sigma_threshold", 3) %}
|
||
|
|
{% set days_to_consider = 14 %}
|
||
|
|
{% set yesterday = "(current_date - interval '1 day')" %}
|
||
|
|
|
||
|
|
with
|
||
|
|
recent_data as (
|
||
|
|
select *
|
||
|
|
from {{ ref("kpis__product_guest_daily_metrics") }}
|
||
|
|
where
|
||
|
|
date_day
|
||
|
|
between {{ yesterday }}
|
||
|
|
- interval '{{ days_to_consider }} "days"' and {{ yesterday }}
|
||
|
|
),
|
||
|
|
metrics_recent_data as (
|
||
|
|
select
|
||
|
|
{% for metric in metric_names %}
|
||
|
|
avg({{ metric }}) as avg_{{ metric }},
|
||
|
|
stddev({{ metric }}) as stddev_{{ metric }}
|
||
|
|
{% if not loop.last %},{% endif %}
|
||
|
|
{% endfor %}
|
||
|
|
from recent_data
|
||
|
|
),
|
||
|
|
outliers as (
|
||
|
|
select
|
||
|
|
rd.date_day,
|
||
|
|
{% for metric in metric_names %}
|
||
|
|
case
|
||
|
|
when
|
||
|
|
abs(rd.{{ metric }} - metrics_recent_data.avg_{{ metric }}) > (
|
||
|
|
metrics_recent_data.stddev_{{ metric }}
|
||
|
|
* {{ sigma_threshold }}
|
||
|
|
)
|
||
|
|
then 1
|
||
|
|
else 0
|
||
|
|
end as is_outlier_{{ metric }}
|
||
|
|
{% if not loop.last %},{% endif %}
|
||
|
|
{% endfor %}
|
||
|
|
from recent_data rd
|
||
|
|
cross join metrics_recent_data
|
||
|
|
where rd.date_day = {{ yesterday }}
|
||
|
|
)
|
||
|
|
select
|
||
|
|
{% for metric in metric_names %}
|
||
|
|
sum(is_outlier_{{ metric }}) as outlier_count_{{ metric }}
|
||
|
|
{% if not loop.last %},{% endif %}
|
||
|
|
{% endfor %}
|
||
|
|
from outliers
|
||
|
|
having
|
||
|
|
{% for metric in metric_names %}
|
||
|
|
sum(is_outlier_{{ metric }}) > 0 {% if not loop.last %} or {% endif %}
|
||
|
|
{% endfor %}
|