diff --git a/macros/get_kpi_dimensions.sql b/macros/get_kpi_dimensions.sql new file mode 100644 index 0000000..b54dc68 --- /dev/null +++ b/macros/get_kpi_dimensions.sql @@ -0,0 +1,13 @@ +/* +Provides a general configuration for the Dimensions available for the KPIs. +Please note that strings should be encoded with " ' your_value_here ' ", + while fields from tables should be specified like " your_field_here " +*/ + +{% macro get_kpi_dimensions() %} + {% set dimensions = [ + {"dimension": "'global'", "dimension_value": "'global'"}, + {"dimension": "'by_number_of_listings'", "dimension_value": "active_accommodations_per_deal_segmentation"} + ] %} + {{ return(dimensions) }} +{% endmacro %} \ No newline at end of file diff --git a/models/intermediate/core/int_core__mtd_booking_metrics.sql b/models/intermediate/core/int_core__mtd_booking_metrics.sql index 77561a2..f30fe9f 100644 --- a/models/intermediate/core/int_core__mtd_booking_metrics.sql +++ b/models/intermediate/core/int_core__mtd_booking_metrics.sql @@ -2,6 +2,9 @@ This model provides Month-To-Date (MTD) based on Booking metrics. */ + +{% set dimensions = get_kpi_dimensions() %} + {{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} with @@ -18,141 +21,102 @@ with -- Created Bookings MTD -- created_year_month as ( - select - d.date, - 'global' as dimension, - 'global' as dimension_value, - count(distinct b.id_booking) as created_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.created_date_utc)::date = d.first_day_month - and extract(day from b.created_date_utc) <= d.day - group by 1, 2, 3 - - union all - - select - d.date, - 'by_number_of_listings' as dimension, - mas.active_accommodations_per_deal_segmentation as dimension_value, - count(distinct b.id_booking) as created_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.created_date_utc)::date = d.first_day_month - and extract(day from b.created_date_utc) <= d.day - inner join int_core__user_host u on b.id_user_host = u.id_user_host - inner join - int_core__mtd_accommodation_segmentation mas - on u.id_deal = mas.id_deal - and d.date = mas.date - group by 1, 2, 3 + {% for dimension in dimensions %} + select + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + count(distinct b.id_booking) as created_bookings + from int_dates_mtd d + inner join int_core__bookings b + on date_trunc('month', b.created_date_utc)::date = d.first_day_month + and extract(day from b.created_date_utc) <= d.day + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join int_core__user_host u on b.id_user_host = u.id_user_host + inner join int_core__mtd_accommodation_segmentation mas + on u.id_deal = mas.id_deal + and d.date = mas.date + {% endif %} + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ), -- Checkout Bookings MTD -- check_out_year_month as ( - select - d.date, - 'global' as dimension, - 'global' as dimension_value, - count(distinct b.id_booking) as check_out_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month - and extract(day from b.check_out_date_utc) <= d.day - group by 1, 2, 3 - - union all - - select - d.date, - 'by_number_of_listings' as dimension, - mas.active_accommodations_per_deal_segmentation as dimension_value, - count(distinct b.id_booking) as check_out_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month - and extract(day from b.check_out_date_utc) <= d.day - inner join int_core__user_host u on b.id_user_host = u.id_user_host - inner join - int_core__mtd_accommodation_segmentation mas - on u.id_deal = mas.id_deal - and d.date = mas.date - group by 1, 2, 3 - + {% for dimension in dimensions %} + select + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + count(distinct b.id_booking) as check_out_bookings + from int_dates_mtd d + inner join int_core__bookings b + on date_trunc('month', b.check_out_date_utc)::date = d.first_day_month + and extract(day from b.check_out_date_utc) <= d.day + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join int_core__user_host u on b.id_user_host = u.id_user_host + inner join int_core__mtd_accommodation_segmentation mas + on u.id_deal = mas.id_deal + and d.date = mas.date + {% endif %} + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ), -- Cancelled Bookings MTD -- cancelled_year_month as ( - select - d.date, - 'global' as dimension, - 'global' as dimension_value, - count(distinct b.id_booking) as cancelled_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.updated_date_utc)::date = d.first_day_month - and extract(day from b.updated_date_utc) <= d.day - and upper(b.booking_state) = {{ var("cancelled_booking_state") }} - group by 1, 2, 3 - - union all - - select - d.date, - 'by_number_of_listings' as dimension, - mas.active_accommodations_per_deal_segmentation as dimension_value, - count(distinct b.id_booking) as cancelled_bookings - from int_dates_mtd d - inner join - int_core__bookings b - on date_trunc('month', b.updated_date_utc)::date = d.first_day_month - and extract(day from b.updated_date_utc) <= d.day - and upper(b.booking_state) = {{ var("cancelled_booking_state") }} - inner join int_core__user_host u on b.id_user_host = u.id_user_host - inner join - int_core__mtd_accommodation_segmentation mas - on u.id_deal = mas.id_deal - and d.date = mas.date - group by 1, 2, 3 + {% for dimension in dimensions %} + select + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + count(distinct b.id_booking) as cancelled_bookings + from int_dates_mtd d + inner join int_core__bookings b + on date_trunc('month', b.updated_date_utc)::date = d.first_day_month + and extract(day from b.updated_date_utc) <= d.day + and upper(b.booking_state) = {{ var("cancelled_booking_state") }} + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join int_core__user_host u on b.id_user_host = u.id_user_host + inner join int_core__mtd_accommodation_segmentation mas + on u.id_deal = mas.id_deal + and d.date = mas.date + {% endif %} + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ), -- Billable Bookings MTD -- billable_year_month as ( - select - d.date, - 'global' as dimension, - 'global' as dimension_value, - count(distinct b.id_booking) as billable_bookings - from int_dates_mtd d - inner join - int_core__booking_charge_events b - on date_trunc('month', b.booking_fee_charge_date_utc)::date - = d.first_day_month - and extract(day from b.booking_fee_charge_date_utc) <= d.day - group by 1, 2, 3 - - union all - - select - d.date, - 'by_number_of_listings' as dimension, - mas.active_accommodations_per_deal_segmentation as dimension_value, - count(distinct bce.id_booking) as billable_bookings - from int_dates_mtd d - inner join - int_core__booking_charge_events bce - on date_trunc('month', bce.booking_fee_charge_date_utc)::date - = d.first_day_month - and extract(day from bce.booking_fee_charge_date_utc) <= d.day - inner join int_core__bookings b on b.id_booking = bce.id_booking - inner join int_core__user_host u on b.id_user_host = u.id_user_host - inner join - int_core__mtd_accommodation_segmentation mas - on u.id_deal = mas.id_deal - and d.date = mas.date - group by 1, 2, 3 + {% for dimension in dimensions %} + select + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + count(distinct bce.id_booking) as billable_bookings + from int_dates_mtd d + inner join int_core__booking_charge_events bce + on date_trunc('month', bce.booking_fee_charge_date_utc)::date = d.first_day_month + and extract(day from bce.booking_fee_charge_date_utc) <= d.day + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join int_core__bookings b on b.id_booking = bce.id_booking + inner join int_core__user_host u on b.id_user_host = u.id_user_host + inner join + int_core__mtd_accommodation_segmentation mas + on u.id_deal = mas.id_deal + and d.date = mas.date + {% endif %} + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} + {% endfor %} ) -- Final aggregation of subqueries -- @@ -189,4 +153,4 @@ left join billable_year_month biym on biym.date = d.date and biym.dimension = d.dimension - and biym.dimension_value = d.dimension_value + and biym.dimension_value = d.dimension_value \ No newline at end of file diff --git a/models/intermediate/cross/int_dates_mtd_by_dimension.sql b/models/intermediate/cross/int_dates_mtd_by_dimension.sql index 0536d81..56dcc2a 100644 --- a/models/intermediate/cross/int_dates_mtd_by_dimension.sql +++ b/models/intermediate/cross/int_dates_mtd_by_dimension.sql @@ -1,4 +1,6 @@ +{% set dimensions = get_kpi_dimensions() %} + {{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} with @@ -7,32 +9,24 @@ with ), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}) -select distinct - d.year, - d.month, - d.day, - d.date, - 'global' as dimension, - 'global' as dimension_value, - d.first_day_month, - d.last_day_month, - d.is_end_of_month, - d.is_current_month -from int_dates_mtd d - -union all - -select distinct - d.year, - d.month, - d.day, - d.date, - 'by_number_of_listings' as dimension, - a.active_accommodations_per_deal_segmentation as dimension_value, - d.first_day_month, - d.last_day_month, - d.is_end_of_month, - d.is_current_month -from int_dates_mtd d -inner join int_core__mtd_accommodation_segmentation a -on d.date = a.date \ No newline at end of file +{% for dimension in dimensions %} + select distinct + d.year, + d.month, + d.day, + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + d.first_day_month, + d.last_day_month, + d.is_end_of_month, + d.is_current_month + from int_dates_mtd d + {% if dimension.dimension == "'by_number_of_listings'" %} + inner join int_core__mtd_accommodation_segmentation a + on d.date = a.date + {% endif %} + {% if not loop.last %} + union all + {% endif %} +{% endfor %}