diff --git a/macros/business_kpis_configuration.sql b/macros/business_kpis_configuration.sql index 3b3f797..6d0ef66 100644 --- a/macros/business_kpis_configuration.sql +++ b/macros/business_kpis_configuration.sql @@ -207,6 +207,15 @@ Provides a general assignement for the Dimensions available for each KPI ] %} {% endif %} + {% if entity_name == "NEW_DASH_CREATED_BOOKINGS" %} + {% set additional_dimensions = additional_dimensions + [ + dim_has_upgraded_service(), + dim_new_dash_version(), + dim_pricing_service(), + dim_pricing_business_type(), + ] %} + {% 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__agg_daily_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__agg_daily_new_dash_created_bookings.sql new file mode 100644 index 0000000..77dd889 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_daily_new_dash_created_bookings.sql @@ -0,0 +1,23 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CREATED_BOOKINGS") %} + +{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + -- Metrics -- + count(distinct cbs.id_booking) as created_bookings + from {{ ref("int_kpis__dimension_dates") }} d + left join + {{ ref("int_kpis__metric_daily_new_dash_created_bookings") }} as cbs + on d.date = cbs.date + where cbs.id_deal is not null + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_created_bookings.sql new file mode 100644 index 0000000..42f5673 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_created_bookings.sql @@ -0,0 +1,20 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CREATED_BOOKINGS") %} + +{{ config(materialized="table", unique_key=["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_bookings) as created_bookings + from {{ ref("int_kpis__metric_monthly_new_dash_created_bookings") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_bookings.sql new file mode 100644 index 0000000..a99ff1d --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_bookings.sql @@ -0,0 +1,20 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CREATED_BOOKINGS") %} + +{{ config(materialized="table", unique_key=["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_bookings) as created_bookings + from {{ ref("int_kpis__metric_weekly_new_dash_created_bookings") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings.sql new file mode 100644 index 0000000..132d451 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings.sql @@ -0,0 +1,43 @@ +{{ + config( + materialized="table", + unique_key=[ + "date", + "id_deal", + "id_user_product_bundle", + "service_name", + "service_business_type", + ], + ) +}} +select + -- Unique Key -- + date(bs.booking_created_date_utc) as date, + bs.id_booking, + bs.id_user_product_bundle, + coalesce(icbsd.service_name) as service_name, + coalesce(icbsd.service_business_type, 'UNSET') as service_business_type, + -- Dimensions -- + coalesce(bs.id_deal, 'UNSET') as id_deal, + case when icbsd.is_upgraded_service then 'YES' else 'NO' end as is_upgraded_service, + coalesce(bs.new_dash_version, 'UNSET') as new_dash_version, + coalesce( + uh.main_billing_country_iso_3_per_deal, 'UNSET' + ) as main_billing_country_iso_3_per_deal, + coalesce( + icmas.active_accommodations_per_deal_segmentation, 'UNSET' + ) as active_accommodations_per_deal_segmentation +from {{ ref("int_core__booking_summary") }} as bs +inner join + {{ ref("int_core__booking_service_detail") }} as icbsd + on bs.id_booking = icbsd.id_booking +inner join {{ ref("int_core__user_host") }} as uh on bs.id_user_host = uh.id_user_host +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on bs.id_deal = icmas.id_deal + and date(icbsd.service_detail_created_at_utc) = icmas.date +where + bs.is_user_in_new_dash = true + and bs.is_missing_id_deal = false + and icbsd.service_detail_created_at_utc + >= bs.user_in_new_dash_since_timestamp_at_utc diff --git a/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings_with_services.sql b/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings_with_services.sql deleted file mode 100644 index cb86f98..0000000 --- a/models/intermediate/kpis/int_kpis__metric_daily_new_dash_created_bookings_with_services.sql +++ /dev/null @@ -1,36 +0,0 @@ -{{ - config( - materialized="table", - unique_key=["id_booking", "service_name", "date", "service_business_type"], - ) -}} -select - -- Unique Key -- - icbs.id_booking, - date(icbs.booking_created_date_utc) as date, - coalesce(icbsd.service_name) as service_name, - coalesce(icbsd.service_business_type, 'UNSET') as service_business_type, - -- Dimensions -- - coalesce(icbs.id_deal, 'UNSET') as id_deal, - case when icbsd.is_upgraded_service then 'YES' else 'NO' end as is_upgraded_service, - coalesce(icbs.new_dash_version, 'UNSET') as new_dash_version, - coalesce( - icd.main_billing_country_iso_3_per_deal, 'UNSET' - ) as main_billing_country_iso_3_per_deal, - coalesce( - icmas.active_accommodations_per_deal_segmentation, 'UNSET' - ) as active_accommodations_per_deal_segmentation -from {{ ref("int_core__booking_summary") }} as icbs -inner join - {{ ref("int_core__booking_service_detail") }} as icbsd - on icbs.id_booking = icbsd.id_booking -left join {{ ref("int_core__deal") }} as icd on icbs.id_deal = icd.id_deal -left join - {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas - on icbs.id_deal = icmas.id_deal - and date(icbsd.service_detail_created_at_utc) = icmas.date -where - icbs.is_user_in_new_dash = true - and icbs.is_missing_id_deal = false - and icbsd.service_detail_created_at_utc - >= icbs.user_in_new_dash_since_timestamp_at_utc diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_created_bookings.sql new file mode 100644 index 0000000..c69b772 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_created_bookings.sql @@ -0,0 +1,33 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "service_name", + "id_deal", + "active_accommodations_per_deal_segmentation", + "service_business_type", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_month as start_date, + d.date as end_date, + cbs.service_name, + cbs.active_accommodations_per_deal_segmentation, + cbs.id_deal, + cbs.service_business_type, + -- Dimensions -- + cbs.new_dash_version, + cbs.is_upgraded_service, + cbs.main_billing_country_iso_3_per_deal, + -- Metrics -- + count(distinct cbs.id_booking) as created_bookings +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_new_dash_created_bookings") }} cbs + on date_trunc('month', cbs.date)::date = d.first_day_month +where d.is_end_of_month = true and cbs.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7, 8, 9 diff --git a/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_bookings.sql b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_bookings.sql new file mode 100644 index 0000000..e611fd7 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_bookings.sql @@ -0,0 +1,33 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "service_name", + "id_deal", + "active_accommodations_per_deal_segmentation", + "service_business_type", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_week as start_date, + d.date as end_date, + cbs.service_name, + cbs.active_accommodations_per_deal_segmentation, + cbs.id_deal, + cbs.service_business_type, + -- Dimensions -- + cbs.new_dash_version, + cbs.is_upgraded_service, + cbs.main_billing_country_iso_3_per_deal, + -- Metrics -- + count(distinct cbs.id_booking) as created_bookings +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_new_dash_created_bookings") }} cbs + on date_trunc('week', cbs.date)::date = d.first_day_week +where d.is_end_of_week = true and cbs.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7, 8, 9 diff --git a/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql b/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql index 701d6c0..0208e83 100644 --- a/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql +++ b/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql @@ -38,6 +38,15 @@ with select * from {{ ref("int_kpis__agg_monthly_new_dash_accommodation_offered_services") }} ), + int_kpis__agg_daily_new_dash_created_bookings as ( + select * from {{ ref("int_kpis__agg_daily_new_dash_created_bookings") }} + ), + int_kpis__agg_weekly_new_dash_created_bookings as ( + select * from {{ ref("int_kpis__agg_weekly_new_dash_created_bookings") }} + ), + int_kpis__agg_monthly_new_dash_created_bookings as ( + select * from {{ ref("int_kpis__agg_monthly_new_dash_created_bookings") }} + ), int_kpis__dimension_dates as (select * from {{ ref("int_kpis__dimension_dates") }}), all_dates as ( select distinct @@ -70,9 +79,7 @@ select accommodation.accommodation_with_offered_service_count, 0 ) as accommodation_with_offered_service_count, coalesce(created.created_services, 0) as created_services, - coalesce( - created.booking_with_created_services_count, 0 - ) as booking_with_created_services_count, + coalesce(bookings.created_bookings, 0) as created_bookings_count, coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, coalesce( chargeable.total_chargeable_amount_in_gbp, 0 @@ -87,19 +94,24 @@ left join and d.dimension_value = created.dimension_value left join int_kpis__agg_daily_new_dash_chargeable_services chargeable - on created.date = chargeable.date - and created.dimension = chargeable.dimension - and created.dimension_value = chargeable.dimension_value + on d.date = chargeable.date + and d.dimension = chargeable.dimension + and d.dimension_value = chargeable.dimension_value left join int_kpis__agg_daily_new_dash_deals_offered_services deals - on created.date = deals.date - and created.dimension = deals.dimension - and created.dimension_value = deals.dimension_value + on d.date = deals.date + and d.dimension = deals.dimension + and d.dimension_value = deals.dimension_value left join int_kpis__agg_daily_new_dash_accommodation_offered_services accommodation - on created.date = accommodation.date - and created.dimension = accommodation.dimension - and created.dimension_value = accommodation.dimension_value + on d.date = accommodation.date + and d.dimension = accommodation.dimension + and d.dimension_value = accommodation.dimension_value +left join + int_kpis__agg_daily_new_dash_created_bookings bookings + on d.date = bookings.date + and d.dimension = bookings.dimension + and d.dimension_value = bookings.dimension_value union all select d.date, @@ -113,9 +125,7 @@ select accommodation.accommodation_with_offered_service_count, 0 ) as accommodation_with_offered_service_count, coalesce(created.created_services, 0) as created_services, - coalesce( - created.booking_with_created_services_count, 0 - ) as booking_with_created_services_count, + coalesce(bookings.created_bookings, 0) as created_bookings_count, coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, coalesce( chargeable.total_chargeable_amount_in_gbp, 0 @@ -130,19 +140,24 @@ left join and d.dimension_value = created.dimension_value left join int_kpis__agg_weekly_new_dash_chargeable_services chargeable - on created.end_date = chargeable.end_date - and created.dimension = chargeable.dimension - and created.dimension_value = chargeable.dimension_value + on d.date = chargeable.end_date + and d.dimension = chargeable.dimension + and d.dimension_value = chargeable.dimension_value left join int_kpis__agg_weekly_new_dash_deals_offered_services deals - on created.end_date = deals.date - and created.dimension = deals.dimension - and created.dimension_value = deals.dimension_value + on d.date = deals.date + and d.dimension = deals.dimension + and d.dimension_value = deals.dimension_value left join int_kpis__agg_weekly_new_dash_accommodation_offered_services accommodation - on created.end_date = accommodation.date - and created.dimension = accommodation.dimension - and created.dimension_value = accommodation.dimension_value + on d.date = accommodation.date + and d.dimension = accommodation.dimension + and d.dimension_value = accommodation.dimension_value +left join + int_kpis__agg_weekly_new_dash_created_bookings bookings + on d.date = bookings.end_date + and d.dimension = bookings.dimension + and d.dimension_value = bookings.dimension_value where d.is_end_of_week union all select @@ -157,9 +172,7 @@ select accommodation.accommodation_with_offered_service_count, 0 ) as accommodation_with_offered_service_count, coalesce(created.created_services, 0) as created_services, - coalesce( - created.booking_with_created_services_count, 0 - ) as booking_with_created_services_count, + coalesce(bookings.created_bookings, 0) as created_bookings_count, coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, coalesce( chargeable.total_chargeable_amount_in_gbp, 0 @@ -174,17 +187,22 @@ left join and d.dimension_value = created.dimension_value left join int_kpis__agg_monthly_new_dash_chargeable_services chargeable - on created.end_date = chargeable.end_date - and created.dimension = chargeable.dimension - and created.dimension_value = chargeable.dimension_value + on d.date = chargeable.end_date + and d.dimension = chargeable.dimension + and d.dimension_value = chargeable.dimension_value left join int_kpis__agg_monthly_new_dash_deals_offered_services deals - on created.end_date = deals.date - and created.dimension = deals.dimension - and created.dimension_value = deals.dimension_value + on d.date = deals.date + and d.dimension = deals.dimension + and d.dimension_value = deals.dimension_value left join int_kpis__agg_monthly_new_dash_accommodation_offered_services accommodation - on created.end_date = accommodation.date - and created.dimension = accommodation.dimension - and created.dimension_value = accommodation.dimension_value + on d.date = accommodation.date + and d.dimension = accommodation.dimension + and d.dimension_value = accommodation.dimension_value +left join + int_kpis__agg_monthly_new_dash_created_bookings bookings + on d.date = bookings.end_date + and d.dimension = bookings.dimension + and d.dimension_value = bookings.dimension_value where d.is_end_of_month diff --git a/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql b/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql index 384abd4..c09e00d 100644 --- a/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql +++ b/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql @@ -11,7 +11,7 @@ select deal_with_offered_service_count as deal_with_offered_service_count, accommodation_with_offered_service_count as accommodation_with_offered_service_count, - booking_with_created_services_count as booking_with_created_services_count, + created_bookings_count as created_bookings_count, total_chargeable_services as total_chargeable_services, total_chargeable_amount_in_gbp as total_chargeable_amount_in_gbp, unique_chargeable_bookings as unique_chargeable_bookings,