# Description New model: * int_kpis__agg_dates_main_kpis - Serves as the skeleton of dates and dimensions for Main KPIs. It's aggregated since it follows a similar aggregation strategy. It's a single model to feed both Main KPIs visualisations. Note boolean fields are real booleans (true/false) while before these were integers (1/0). This also affects downstream models. Main KPIs flow adaptations to new skeleton model: * int_monthly_aggregated_metrics_history_by_deal * int_monthly_churn_metrics - additionally, calls usual KPIs macro instead of old one * int_mtd_vs_previous_year_metrics Reporting changes to ensure report is not down: * mtd_aggregated_metrics - adaptations on booleans (true-1, false-0) Cleaning: * get_kpi_dimensions macro is no longer used * int_dates_by_deal model and schema entry * int_dates_mtd_by_dimension model and schema entry * int_dates_mtd model and schema entry # 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. - [X] 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: #23763
83 lines
3.3 KiB
SQL
83 lines
3.3 KiB
SQL
{% set production_dimensions = get_kpi_dimensions_for_production() %}
|
|
|
|
with
|
|
dimensions as (
|
|
{% for dimension in production_dimensions %}
|
|
select
|
|
{{ dimension.dimension }} as dimension,
|
|
{{ dimension.dimension_display }} as dimension_display
|
|
{% if not loop.last %}
|
|
union all
|
|
{% endif %}
|
|
{% endfor %}
|
|
),
|
|
int_mtd_aggregated_metrics as (
|
|
select m.*, d.dimension_display
|
|
from {{ ref("int_mtd_aggregated_metrics") }} m
|
|
-- The following clause limits the display execution
|
|
-- to only include those dimensions configured to
|
|
-- appear for production purposes
|
|
inner join dimensions d on m.dimension = d.dimension
|
|
)
|
|
|
|
select
|
|
year as year,
|
|
month as month,
|
|
day as day,
|
|
case when is_end_of_month then 1 else 0 end as is_end_of_month,
|
|
case when is_current_month then 1 else 0 end as is_current_month,
|
|
first_day_month as first_day_month,
|
|
date as date,
|
|
dimension_display as dimension,
|
|
dimension_value as dimension_value,
|
|
previous_year_date as previous_year_date,
|
|
order_by as order_by,
|
|
number_format as number_format,
|
|
metric as metric,
|
|
value as value,
|
|
previous_year_value as previous_year_value,
|
|
relative_increment as relative_increment,
|
|
relative_increment_with_sign_format as relative_increment_with_sign_format
|
|
from int_mtd_aggregated_metrics
|
|
/*
|
|
The following where condition is applied to avoid displaying revenue metrics
|
|
in the MTD for the current month and the previous month. The main reason is
|
|
that we have a time delay between when the guest does a payment vs. when we
|
|
invoice or credit hosts (Xero). Same applies for Host Resolutions.
|
|
This is specially tricky for the Host-takes-waiver revenue: guests payments
|
|
happen in a timely fashion, and we get all waiver money from the guests. Once
|
|
the month is finished, Finance will start to invoice hosts, and in this case,
|
|
all hosts that have the Host-takes-waiver need to be payed back the amount
|
|
coming from the guest.
|
|
Not having this filter would mean that, in the current month, the figures
|
|
displayed of guest revenue would be much larger than they actually will be
|
|
because we still need to pay back to the hosts these waivers.
|
|
For a more current-month evaluation, Guest Payments should be a good proxy
|
|
metric to follow.
|
|
*/
|
|
where
|
|
(
|
|
(
|
|
-- Not show current + previous month if the metric depends on invoicing
|
|
-- cycle
|
|
(
|
|
lower(metric) like '%total revenue%'
|
|
or lower(metric) like '%resolutions%'
|
|
or lower(metric) like '%invoiced%'
|
|
or lower(metric) like '%retained%'
|
|
or lower(metric) like '%damage host%'
|
|
)
|
|
and {{ is_date_before_previous_month("date") }}
|
|
)
|
|
-- Keep all history for the rest of metrics
|
|
or not
|
|
(
|
|
lower(metric) like '%total revenue%'
|
|
or lower(metric) like '%resolutions%'
|
|
or lower(metric) like '%invoiced%'
|
|
or lower(metric) like '%retained%'
|
|
or lower(metric) like '%damage host%'
|
|
)
|
|
)
|
|
-- If metric is Churn Rate, do not show month in progress
|
|
and not (lower(metric) like '%churn rate%' and is_current_month = true)
|