# Description After the name change of the metric, the exclusion in reporting for the ongoing month and previous month is not working for the new MRR metric. This PR aims to fix it. # Checklist - [ ] The edited models and dependants run properly with production data. - [ ] The edited models are sufficiently documented. - [ ] The edited models contain PK tests, and I've ran and passed them. - [ ] I have checked for DRY opportunities with other models and docs. - [ ] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Fixes exclusion of MRR after name change Related work items: #26621
88 lines
3.5 KiB
SQL
88 lines
3.5 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,
|
|
case
|
|
when is_end_of_month_or_yesterday then 1 else 0
|
|
end as is_end_of_month_or_yesterday,
|
|
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 '%mrr%'
|
|
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 '%mrr%'
|
|
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)
|