Weekly aggregated model
This commit is contained in:
parent
d8a064fd06
commit
7e786649cc
3 changed files with 173 additions and 2 deletions
|
|
@ -0,0 +1,38 @@
|
||||||
|
{% set dimensions = get_kpi_dimensions_per_model("CHECK_IN_ATTRIBUTED_GUEST_JOURNEYS") %}
|
||||||
|
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="table", unique_key=["end_date", "dimension", "dimension_value"]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
|
||||||
|
{% for dimension in dimensions %}
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
start_date,
|
||||||
|
end_date,
|
||||||
|
week,
|
||||||
|
{{ dimension.dimension }} as dimension,
|
||||||
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
|
-- Metrics --
|
||||||
|
sum(
|
||||||
|
created_guest_journeys_not_cancelled
|
||||||
|
) as created_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
started_guest_journeys_not_cancelled
|
||||||
|
) as started_guest_journeys_not_cancelled,
|
||||||
|
sum(
|
||||||
|
completed_guest_journeys_not_cancelled
|
||||||
|
) as completed_guest_journeys_not_cancelled,
|
||||||
|
sum(created_guest_journeys) as created_guest_journeys,
|
||||||
|
sum(started_guest_journeys) as started_guest_journeys,
|
||||||
|
sum(completed_guest_journeys) as completed_guest_journeys,
|
||||||
|
sum(count_csat_score) as count_csat_score,
|
||||||
|
sum(count_csat_score * average_csat_score) / nullif(sum(count_csat_score), 0) as average_csat_score
|
||||||
|
from {{ ref("int_kpis__metric_weekly_check_in_attributed_guest_journeys") }}
|
||||||
|
group by 1, 2, 3, 4, 5
|
||||||
|
{% if not loop.last %}
|
||||||
|
union all
|
||||||
|
{% endif %}
|
||||||
|
{% endfor %}
|
||||||
|
|
@ -13,8 +13,8 @@ with
|
||||||
id.date_day as date,
|
id.date_day as date,
|
||||||
id.month_start_date as first_day_month,
|
id.month_start_date as first_day_month,
|
||||||
id.month_end_date as last_day_month,
|
id.month_end_date as last_day_month,
|
||||||
id.week_start_date as first_day_week,
|
id.iso_week_start_date as first_day_week,
|
||||||
id.week_end_date as last_day_week,
|
id.iso_week_end_date as last_day_week,
|
||||||
now()::date as today
|
now()::date as today
|
||||||
from int_dates id
|
from int_dates id
|
||||||
)
|
)
|
||||||
|
|
|
||||||
|
|
@ -3667,6 +3667,139 @@ models:
|
||||||
max_value: 5
|
max_value: 5
|
||||||
strictly: false
|
strictly: false
|
||||||
|
|
||||||
|
- name: int_kpis__agg_weekly_check_in_attributed_guest_journeys
|
||||||
|
description: |
|
||||||
|
This model computes the dimension aggregation for Weekly metrics associated
|
||||||
|
to Guest Journeys attributed to Check-In date.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- end_date
|
||||||
|
- dimension
|
||||||
|
- dimension_value
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: start_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The start date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: end_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The end date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: week
|
||||||
|
data_type: int
|
||||||
|
description: Week number of the given date.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: dimension
|
||||||
|
data_type: text
|
||||||
|
description: |
|
||||||
|
The dimension or granularity of the metrics.
|
||||||
|
tests:
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: created_guest_journeys_not_cancelled
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: started_guest_journeys_not_cancelled
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: completed_guest_journeys_not_cancelled
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: created_guest_journeys
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: started_guest_journeys
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: completed_guest_journeys
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: count_csat_score
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- global
|
||||||
|
- by_deal
|
||||||
|
- by_has_payment
|
||||||
|
- by_has_id_check
|
||||||
|
- by_billing_country
|
||||||
|
- by_number_of_listings
|
||||||
|
|
||||||
|
- name: dimension_value
|
||||||
|
data_type: text
|
||||||
|
description: |
|
||||||
|
The value or segment available for the selected dimension.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: created_guest_journeys_not_cancelled
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys created, excluding
|
||||||
|
cancelled bookings, for a given date, dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: started_guest_journeys_not_cancelled
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys started, excluding
|
||||||
|
cancelled bookings, for a given date, dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: completed_guest_journeys_not_cancelled
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys completed, excluding
|
||||||
|
cancelled bookings, for a given date, dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: created_guest_journeys
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys created for a given date,
|
||||||
|
dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: started_guest_journeys
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys started for a given date,
|
||||||
|
dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: completed_guest_journeys
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys completed for a given date,
|
||||||
|
dimension, and value.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: count_csat_score
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated count of guest journeys with CSAT
|
||||||
|
(customer satisfaction score) in a given date, dimension, and value.
|
||||||
|
|
||||||
|
- name: average_csat_score
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
Weekly aggregated average CSAT score in a given date,
|
||||||
|
dimension, and value.
|
||||||
|
tests:
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: 5
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: int_kpis__metric_mtd_check_in_attributed_guest_journeys
|
- name: int_kpis__metric_mtd_check_in_attributed_guest_journeys
|
||||||
description: |
|
description: |
|
||||||
This model computes the Month-To-Date metrics associated with Guest Journeys
|
This model computes the Month-To-Date metrics associated with Guest Journeys
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue