diff --git a/macros/business_kpis_configuration.sql b/macros/business_kpis_configuration.sql index e41f317..7dba2e5 100644 --- a/macros/business_kpis_configuration.sql +++ b/macros/business_kpis_configuration.sql @@ -107,6 +107,11 @@ Provides a general assignemnt for the Dimensions available for each KPI {% set additional_dimensions = [dim_dash()] %} {% endif %} + {# Add entity-specific dimensions #} + {% if entity_name == "GUEST_JOURNEY_METRICS" %} + {% set additional_dimensions = [dim_has_payment(), dim_has_id_check()] %} + {% endif %} + {# Combine base dimensions with additional dimensions for the specific model #} {% set dimensions = base_dimensions + additional_dimensions %} {{ return(dimensions) }} diff --git a/models/intermediate/kpis/int_kpis__aggregated_monthly_check_in_attributed_guest_journeys.sql b/models/intermediate/kpis/int_kpis__aggregated_monthly_check_in_attributed_guest_journeys.sql new file mode 100644 index 0000000..8190595 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__aggregated_monthly_check_in_attributed_guest_journeys.sql @@ -0,0 +1,35 @@ +{% set dimensions = get_kpi_dimensions_per_model("GUEST_JOURNEY_METRICS") %} + +{{ + config( + materialized="table", unique_key=["end_date", "dimension", "dimension_value"] + ) +}} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + start_date, + end_date, + {{ 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 + from {{ ref("int_kpis__metric_monthly_check_in_attributed_guest_journeys") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_check_in_attributed_guest_journeys.sql b/models/intermediate/kpis/int_kpis__metric_monthly_check_in_attributed_guest_journeys.sql new file mode 100644 index 0000000..c47a0e7 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_monthly_check_in_attributed_guest_journeys.sql @@ -0,0 +1,32 @@ +{{ + config( + materialized="view", + unique_key=["end_date", "id_deal", "has_payment", "has_id_check"], + ) +}} + +select + -- Unique Key -- + d.first_day_month as start_date, + d.date as end_date, + b.id_deal, + b.has_payment, + b.has_id_check, + -- Dimensions -- + b.active_accommodations_per_deal_segmentation, + b.main_billing_country_iso_3_per_deal, + -- Metrics -- + sum(b.created_guest_journeys_not_cancelled) as created_guest_journeys_not_cancelled, + sum(b.started_guest_journeys_not_cancelled) as started_guest_journeys_not_cancelled, + sum( + b.completed_guest_journeys_not_cancelled + ) as completed_guest_journeys_not_cancelled, + sum(b.created_guest_journeys) as created_guest_journeys, + sum(b.started_guest_journeys) as started_guest_journeys, + sum(b.completed_guest_journeys) as completed_guest_journeys +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} b + on date_trunc('month', b.date)::date = d.first_day_month +where d.is_end_of_month = true and b.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7 diff --git a/models/intermediate/kpis/int_kpis__metric_mtd_check_in_attributed_guest_journeys.sql b/models/intermediate/kpis/int_kpis__metric_mtd_check_in_attributed_guest_journeys.sql new file mode 100644 index 0000000..fce8ec6 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_mtd_check_in_attributed_guest_journeys.sql @@ -0,0 +1,33 @@ +{{ + config( + materialized="view", + unique_key=["end_date", "id_deal", "has_payment", "has_id_check"], + ) +}} + +select + -- Unique Key -- + d.first_day_month as start_date, + d.date as end_date, + b.id_deal, + b.has_payment, + b.has_id_check, + -- Dimensions -- + b.active_accommodations_per_deal_segmentation, + b.main_billing_country_iso_3_per_deal, + -- Metrics -- + sum(b.created_guest_journeys_not_cancelled) as created_guest_journeys_not_cancelled, + sum(b.started_guest_journeys_not_cancelled) as started_guest_journeys_not_cancelled, + sum( + b.completed_guest_journeys_not_cancelled + ) as completed_guest_journeys_not_cancelled, + sum(b.created_guest_journeys) as created_guest_journeys, + sum(b.started_guest_journeys) as started_guest_journeys, + sum(b.completed_guest_journeys) as completed_guest_journeys +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} b + on date_trunc('month', b.date)::date = d.first_day_month + and extract(day from b.date) <= d.day +where d.is_month_to_date = true and b.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7 \ No newline at end of file