Merged PR 2246: KPIs refactor: naming convention and PBI sources replication
Changing naming to follow convention. This PR has the following changes: - the model `int_core__mtd_aggregated_metrics` has been moved to cross and changed the name to `int_mtd_aggregated_metrics` - the model `int_core__monthly_aggregated_metrics_history_by_deal` has been moved to cross and changed the name to `int_monthly_aggregated_metrics_history_by_deal` - the reporting models `core__mtd_aggregated_metrics` and `core__monthly_aggregated_metrics_history_by_deal` now source the `int_mtd_aggregated_metrics` and `int_monthly_aggregated_metrics_history_by_deal` to avoid breaking the production dashboard - the reporting models have been duplicated from core into general with the correct names, i.e., `mtd_aggregated_metrics` and `monthly_aggregated_metrics_history_by_deal` - Documentation has been moved in intermediate and replicated in reporting, adding comments on the currently in use models that are going to die soon. This will allow for a transition of the PBI dashboard from one source to another. Exposures file still not touched since technically the report is still sourcing the 'legacy' models. Documentation of the refactor here: https://www.notion.so/knowyourguest-superhog/Refactoring-Business-KPIs-5deb6aadddb34884ae90339402ac16e3 Related work items: #18202
This commit is contained in:
parent
976ac70949
commit
20e7220ffe
10 changed files with 350 additions and 138 deletions
|
|
@ -0,0 +1,49 @@
|
|||
/*
|
||||
This model aggregates the different metrics by deal for those hosts that have it assigned.
|
||||
|
||||
*/
|
||||
|
||||
with
|
||||
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
|
||||
int_core__mtd_deal_lifecycle as (select * from {{ ref("int_core__mtd_deal_lifecycle") }}),
|
||||
int_core__monthly_guest_journey_history_by_deal as (select * from {{ ref("int_core__monthly_guest_journey_history_by_deal") }}),
|
||||
int_core__monthly_accommodation_history_by_deal as (select * from {{ ref("int_core__monthly_accommodation_history_by_deal") }}),
|
||||
int_core__monthly_booking_history_by_deal as (select * from {{ ref("int_core__monthly_booking_history_by_deal") }})
|
||||
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
l.deal_lifecycle_state,
|
||||
b.created_bookings,
|
||||
b.check_out_bookings,
|
||||
b.cancelled_bookings,
|
||||
gj.created_guest_journeys,
|
||||
gj.started_guest_journeys,
|
||||
gj.completed_guest_journeys,
|
||||
gj.start_rate_guest_journey,
|
||||
gj.completion_rate_guest_journey,
|
||||
gj.incompletion_rate_guest_journey,
|
||||
a.new_listings,
|
||||
a.first_time_booked_listings,
|
||||
a.churning_listings,
|
||||
a.listings_booked_in_month,
|
||||
a.listings_booked_in_6_months,
|
||||
a.listings_booked_in_12_months
|
||||
from int_dates_by_deal d
|
||||
left join int_core__mtd_deal_lifecycle l
|
||||
on d.date = l.date
|
||||
and d.id_deal = l.id_deal
|
||||
left join int_core__monthly_booking_history_by_deal b
|
||||
on d.date = b.date
|
||||
and d.id_deal = b.id_deal
|
||||
left join int_core__monthly_guest_journey_history_by_deal gj
|
||||
on d.date = gj.date
|
||||
and d.id_deal = gj.id_deal
|
||||
left join int_core__monthly_accommodation_history_by_deal a
|
||||
on d.date = a.date
|
||||
and d.id_deal = a.id_deal
|
||||
|
||||
|
||||
195
models/intermediate/cross/int_mtd_aggregated_metrics.sql
Normal file
195
models/intermediate/cross/int_mtd_aggregated_metrics.sql
Normal file
|
|
@ -0,0 +1,195 @@
|
|||
{% set metrics = [
|
||||
{
|
||||
"order_by": 1,
|
||||
"metric": "Created Bookings",
|
||||
"value": "created_bookings",
|
||||
"previous_year_value": "previous_year_created_bookings",
|
||||
"relative_increment": "relative_increment_created_bookings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 2,
|
||||
"metric": "Cancelled Bookings",
|
||||
"value": "cancelled_bookings",
|
||||
"previous_year_value": "previous_year_cancelled_bookings",
|
||||
"relative_increment": "relative_increment_cancelled_bookings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 3,
|
||||
"metric": "Checkout Bookings",
|
||||
"value": "check_out_bookings",
|
||||
"previous_year_value": "previous_year_check_out_bookings",
|
||||
"relative_increment": "relative_increment_check_out_bookings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 4,
|
||||
"metric": "Guest Journey Created",
|
||||
"value": "created_guest_journeys",
|
||||
"previous_year_value": "previous_year_created_guest_journeys",
|
||||
"relative_increment": "relative_increment_created_guest_journeys",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 5,
|
||||
"metric": "Guest Journey Started",
|
||||
"value": "started_guest_journeys",
|
||||
"previous_year_value": "previous_year_started_guest_journeys",
|
||||
"relative_increment": "relative_increment_started_guest_journeys",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 6,
|
||||
"metric": "Guest Journey Completed",
|
||||
"value": "completed_guest_journeys",
|
||||
"previous_year_value": "previous_year_completed_guest_journeys",
|
||||
"relative_increment": "relative_increment_completed_guest_journeys",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 7,
|
||||
"metric": "New Deals",
|
||||
"value": "new_deals",
|
||||
"previous_year_value": "previous_year_new_deals",
|
||||
"relative_increment": "relative_increment_new_deals",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 8,
|
||||
"metric": "First Time Booked Deals",
|
||||
"value": "first_time_booked_deals",
|
||||
"previous_year_value": "previous_year_first_time_booked_deals",
|
||||
"relative_increment": "relative_increment_first_time_booked_deals",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 9,
|
||||
"metric": "Deals Booked in Month",
|
||||
"value": "deals_booked_in_month",
|
||||
"previous_year_value": "previous_year_deals_booked_in_month",
|
||||
"relative_increment": "relative_increment_deals_booked_in_month",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 10,
|
||||
"metric": "Deals Booked in 6 Months",
|
||||
"value": "deals_booked_in_6_months",
|
||||
"previous_year_value": "previous_year_deals_booked_in_6_months",
|
||||
"relative_increment": "relative_increment_deals_booked_in_6_months",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 11,
|
||||
"metric": "Deals Booked in 12 Months",
|
||||
"value": "deals_booked_in_12_months",
|
||||
"previous_year_value": "previous_year_deals_booked_in_12_months",
|
||||
"relative_increment": "relative_increment_deals_booked_in_12_months",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 12,
|
||||
"metric": "Churning Deals",
|
||||
"value": "churning_deals",
|
||||
"previous_year_value": "previous_year_churning_deals",
|
||||
"relative_increment": "relative_increment_churning_deals",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 13,
|
||||
"metric": "New Listings",
|
||||
"value": "new_listings",
|
||||
"previous_year_value": "previous_year_new_listings",
|
||||
"relative_increment": "relative_increment_new_listings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 14,
|
||||
"metric": "First Time Booked Listings",
|
||||
"value": "first_time_booked_listings",
|
||||
"previous_year_value": "previous_year_first_time_booked_listings",
|
||||
"relative_increment": "relative_increment_first_time_booked_listings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 15,
|
||||
"metric": "Listings Booked in Month",
|
||||
"value": "listings_booked_in_month",
|
||||
"previous_year_value": "previous_year_listings_booked_in_month",
|
||||
"relative_increment": "relative_increment_listings_booked_in_month",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 16,
|
||||
"metric": "Listings Booked in 6 Months",
|
||||
"value": "listings_booked_in_6_months",
|
||||
"previous_year_value": "previous_year_listings_booked_in_6_months",
|
||||
"relative_increment": "relative_increment_listings_booked_in_6_months",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 17,
|
||||
"metric": "Listings Booked in 12 Months",
|
||||
"value": "listings_booked_in_12_months",
|
||||
"previous_year_value": "previous_year_listings_booked_in_12_months",
|
||||
"relative_increment": "relative_increment_listings_booked_in_12_months",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 18,
|
||||
"metric": "Churning Listings",
|
||||
"value": "churning_listings",
|
||||
"previous_year_value": "previous_year_churning_listings",
|
||||
"relative_increment": "relative_increment_churning_listings",
|
||||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"order_by": 19,
|
||||
"metric": "Guest Journey Start Rate",
|
||||
"value": "start_rate_guest_journey",
|
||||
"previous_year_value": "previous_year_start_rate_guest_journey",
|
||||
"relative_increment": "relative_increment_start_rate_guest_journey",
|
||||
"number_format": "percentage",
|
||||
},
|
||||
{
|
||||
"order_by": 20,
|
||||
"metric": "Guest Journey Completion Rate",
|
||||
"value": "completion_rate_guest_journey",
|
||||
"previous_year_value": "previous_year_completion_rate_guest_journey",
|
||||
"relative_increment": "relative_increment_completion_rate_guest_journey",
|
||||
"number_format": "percentage",
|
||||
},
|
||||
{
|
||||
"order_by": 21,
|
||||
"metric": "Guest Journey Incompletion Rate",
|
||||
"value": "incompletion_rate_guest_journey",
|
||||
"previous_year_value": "previous_year_incompletion_rate_guest_journey",
|
||||
"relative_increment": "relative_increment_incompletion_rate_guest_journey",
|
||||
"number_format": "percentage",
|
||||
},
|
||||
] %}
|
||||
with
|
||||
int_mtd_vs_previous_year_metrics as (
|
||||
select * from {{ ref("int_mtd_vs_previous_year_metrics") }}
|
||||
)
|
||||
{% for metric in metrics %}
|
||||
select
|
||||
year,
|
||||
month,
|
||||
day,
|
||||
is_end_of_month,
|
||||
is_current_month,
|
||||
date,
|
||||
previous_year_date,
|
||||
{{ metric.order_by }} as order_by,
|
||||
-- quotation marks added because text format
|
||||
'{{ metric.number_format }}' as number_format,
|
||||
'{{ metric.metric }}' as metric,
|
||||
{{ metric.value }} as value,
|
||||
{{ metric.previous_year_value }} as previous_year_value,
|
||||
{{ metric.relative_increment }} as relative_increment
|
||||
from int_mtd_vs_previous_year_metrics
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
|
|
@ -182,6 +182,141 @@ models:
|
|||
tests:
|
||||
- not_null
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: Id of the deal associated to the host.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_mtd_aggregated_metrics
|
||||
description: |
|
||||
The `int_mtd_aggregated_metrics` model aggregates multiple metrics on a year, month, and day basis.
|
||||
The primary source of data is the `int_mtd_vs_previous_year_metrics` model, which contain the combination
|
||||
of metrics data per source. This model just changes the display format to unpivot the information into
|
||||
a set of metric, value, previous_year_value and relative_increment at a given date. It uses Jinja
|
||||
code to avoid code replication.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- metric
|
||||
|
||||
columns:
|
||||
- name: year
|
||||
data_type: int
|
||||
description: year number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: month
|
||||
data_type: int
|
||||
description: month number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: day
|
||||
data_type: int
|
||||
description: day monthly number of the given date.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: is_end_of_month
|
||||
data_type: boolean
|
||||
description: is end of month, 1 for yes, 0 for no.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: is_current_month
|
||||
data_type: boolean
|
||||
description: |
|
||||
checks if the date is within the current executed month,
|
||||
1 for yes, 0 for no.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: date
|
||||
data_type: date
|
||||
description: |
|
||||
main date for the computation, that is used for filters.
|
||||
It comes from int_dates_mtd logic.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: previous_year_date
|
||||
data_type: date
|
||||
description: |
|
||||
corresponds to the date of the previous year, with respect to the field date.
|
||||
It comes from int_dates_mtd logic. It's only displayed for information purposes,
|
||||
should not be needed for reporting.
|
||||
|
||||
- name: metric
|
||||
data_type: text
|
||||
description: name of the business metric.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: order_by
|
||||
data_type: integer
|
||||
description: |
|
||||
order for displaying purposes. Null values are accepted, but keep
|
||||
in mind that then there's no default controlled display order.
|
||||
|
||||
- name: number_format
|
||||
data_type: text
|
||||
description: allows for grouping and formatting for displaying purposes.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values: ['integer', 'percentage']
|
||||
|
||||
- name: value
|
||||
data_type: numeric
|
||||
description: |
|
||||
numeric value (integer or decimal) that corresponds to the MTD computation of the metric
|
||||
at a given date.
|
||||
|
||||
- name: previous_year_value
|
||||
data_type: numeric
|
||||
description: |
|
||||
numeric value (integer or decimal) that corresponds to the MTD computation of the metric
|
||||
on the previous year at a given date.
|
||||
|
||||
- name: relative_increment
|
||||
data_type: numeric
|
||||
description: |
|
||||
numeric value that corresponds to the relative increment between value and previous year value,
|
||||
following the computation: value / previous_year_value - 1.
|
||||
|
||||
|
||||
- name: int_monthly_aggregated_metrics_history_by_deal
|
||||
description: |
|
||||
This model aggregates the monthly historic information regarding the different metrics computed
|
||||
at deal level. The primary sources of data are the `int_yyy__monthly_XXXXX_history_by_deal`
|
||||
models which contain the raw metrics data per source.
|
||||
|
||||
Unlike the int_mtd_aggregated_metrics, this model does not abstract each metric, since
|
||||
no comparison versus last year is performed. In short, it just gathers the information stored
|
||||
in the abovementioned models.
|
||||
|
||||
To keep in mind: aggregating the information of this model will not necessarily result into
|
||||
the int_mtd_aggregated metrics because 1) the mtd version contains more computing dates
|
||||
than the by deal version, the latest being a subset of the first, and 2) the deal based model
|
||||
enforces that a booking/guest journey/listing/etc has a host with a deal assigned, which is
|
||||
not necessarily the case.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The last day of the month or yesterday for historic metrics.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: Id of the deal associated to the host.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue