diff --git a/macros/business_kpis_configuration.sql b/macros/business_kpis_configuration.sql index a369d78..ba3b9ff 100644 --- a/macros/business_kpis_configuration.sql +++ b/macros/business_kpis_configuration.sql @@ -102,20 +102,27 @@ Provides a general assignemnt for the Dimensions available for each KPI dim_global(), dim_number_of_listings(), dim_billing_country(), - dim_deal(), ] %} {# Initialize a list to hold any model-specific dimensions #} {% set additional_dimensions = [] %} + {# Adds Deal dimension to all models except DEAL metrics #} + {% if entity_name != "DEALS" %} + {% set additional_dimensions = additional_dimensions + [dim_deal()] %} + {% endif %} + {# Add entity-specific dimensions #} {% if entity_name == "CREATED_BOOKINGS" %} - {% set additional_dimensions = [dim_dash()] %} + {% set additional_dimensions = additional_dimensions + [dim_dash()] %} {% endif %} {# Add entity-specific dimensions #} {% if entity_name == "CHECK_IN_ATTRIBUTED_GUEST_JOURNEYS" %} - {% set additional_dimensions = [dim_has_payment(), dim_has_id_check()] %} + {% set additional_dimensions = additional_dimensions + [ + dim_has_payment(), + dim_has_id_check(), + ] %} {% endif %} {# Combine base dimensions with additional dimensions for the specific model #} diff --git a/models/intermediate/cross/int_mtd_deal_lifecycle.sql b/models/intermediate/cross/int_mtd_deal_lifecycle.sql index ba7106f..677f360 100644 --- a/models/intermediate/cross/int_mtd_deal_lifecycle.sql +++ b/models/intermediate/cross/int_mtd_deal_lifecycle.sql @@ -6,7 +6,7 @@ Assumes a host will have a deal being filled. {{ config(materialized="table", unique_key=["date", "id_deal"]) }} with int_core__bookings as (select * from {{ ref("int_core__bookings") }}), - int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}), @@ -44,10 +44,10 @@ with max(b.created_date_utc) as last_time_booked_date_utc, max(b.previous_booked_date) as second_to_last_time_booked_date_utc from int_dates_mtd d - inner join int_core__unified_user h on d.date >= h.created_date_utc + inner join int_core__user_host h on d.date >= date(h.created_date_utc) left join booked_days_per_host b - on h.id_user = b.id_user_host + on h.id_user_host = b.id_user_host and d.date >= b.created_date_utc where h.id_deal is not null group by d.date, h.id_deal diff --git a/models/intermediate/kpis/int_kpis__agg_daily_deals.sql b/models/intermediate/kpis/int_kpis__agg_daily_deals.sql new file mode 100644 index 0000000..7cf8655 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_daily_deals.sql @@ -0,0 +1,33 @@ +{% set dimensions = get_kpi_dimensions_per_model("DEALS") %} + +{{ 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, + -- Date Attributes -- + d.is_current_month, + d.is_end_of_month, + d.is_month_to_date, + -- Metrics -- + sum(new_deals) as new_deals, + sum(never_booked_deals) as never_booked_deals, + sum(first_time_booked_deals) as first_time_booked_deals, + sum(active_deals) as active_deals, + sum(churning_deals) as churning_deals, + sum(inactive_deals) as inactive_deals, + sum(reactivated_deals) as reactivated_deals, + sum(deals_booked_in_month) as deals_booked_in_month, + sum(deals_booked_in_6_months) as deals_booked_in_6_months, + sum(deals_booked_in_12_months) as deals_booked_in_12_months + from {{ ref("int_kpis__dimension_dates") }} d + left join {{ ref("int_kpis__metric_daily_deals") }} as mdd on d.date = mdd.date + group by 1, 2, 3, 4, 5, 6 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__lifecycle_daily_deal.sql b/models/intermediate/kpis/int_kpis__lifecycle_daily_deal.sql new file mode 100644 index 0000000..6f6e2b9 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__lifecycle_daily_deal.sql @@ -0,0 +1,219 @@ +/* +This model provides Month-To-Date (MTD) deal lifecycle based on booking metrics. +Assumes a host will have a deal being filled. + +*/ +{{ config(materialized="table", unique_key=["date", "id_deal"]) }} +with + int_core__bookings as (select * from {{ ref("int_core__bookings") }}), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_kpis__dimension_dates as (select * from {{ ref("int_kpis__dimension_dates") }}), + int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}), + + hubspot_deal_offboardings as ( + -- At the moment it's not possible to account for deal reactivation within + -- hubspot, meaning, once a deal has a cancellation date we'll be considering + -- it as churned. However, a deal can be reactivated and if so, the + -- cancellation date might be set up to null, thus loosing the previous + -- history of offboarding and affecting backwards history. Lastly, + -- cancellation date not being null is preferred vs. the hubspot deal stage + -- since an actual churned deal might be in a process of reactivation, + -- discussing with our colleagues from sales / am teams. In this discussion + -- period, the stage could be different than cancelled, but still not + -- reactivated. + select id_deal, cancellation_date_utc + from int_hubspot__deal + where cancellation_date_utc is not null + ), + booked_days_per_deal as ( + select + icuh.id_deal, + icb.created_date_utc, + lag(icb.created_date_utc, 1) over ( + partition by icuh.id_deal order by icb.created_date_utc asc + ) as previous_booked_date + from int_core__bookings icb + inner join int_core__user_host icuh on icb.id_user_host = icuh.id_user_host + where icuh.id_deal is not null + group by icuh.id_deal, icb.created_date_utc + ), + deal_historic_booking_dates as ( + select + d.date, + h.id_deal, + min(date(h.created_date_utc)) as creation_date_utc, + min(b.created_date_utc) as first_time_booked_date_utc, + max(b.created_date_utc) as last_time_booked_date_utc, + max(b.previous_booked_date) as second_to_last_time_booked_date_utc + from int_kpis__dimension_dates d + inner join int_core__user_host h on d.date >= date(h.created_date_utc) + left join + booked_days_per_deal b + on h.id_deal = b.id_deal + and d.date >= b.created_date_utc + where h.id_deal is not null + group by d.date, h.id_deal + ), + deal_historic_features as ( + select + hhbf.date, + hhbf.id_deal, + hhbf.creation_date_utc, + hhbf.first_time_booked_date_utc, + hhbf.last_time_booked_date_utc, + hhbf.second_to_last_time_booked_date_utc, + hdo.cancellation_date_utc, + case + when hhbf.date >= hdo.cancellation_date_utc then true else false + end as deal_has_been_offboarded, + case + when + date_trunc('month', hdo.cancellation_date_utc) + = date_trunc('month', hhbf.date) + then true + else false + end as deal_was_offboarded_this_month, + case + when hhbf.first_time_booked_date_utc is not null then true else false + end as deal_has_at_least_one_booking, + case + when + date_trunc('month', hhbf.creation_date_utc) + = date_trunc('month', hhbf.date) + then true + else false + end as deal_was_created_this_month, + case + when + date_trunc('month', hhbf.first_time_booked_date_utc) + = date_trunc('month', hhbf.last_time_booked_date_utc) + then true + else false + end as deal_has_first_booking, + case + when + date_trunc('month', hhbf.last_time_booked_date_utc) + = date_trunc('month', hhbf.date) + then true + else false + end as has_been_booked_within_current_month, + case + when + date_trunc('month', hhbf.last_time_booked_date_utc) + + interval '6 months' + > date_trunc('month', hhbf.date) + then true + else false + end as has_been_booked_within_last_6_months, + case + when + date_trunc('month', hhbf.last_time_booked_date_utc) + + interval '12 months' + > date_trunc('month', hhbf.date) + then true + else false + end as has_been_booked_within_last_12_months, + case + when + date_trunc('month', hhbf.last_time_booked_date_utc) + + interval '12 months' + = date_trunc('month', hhbf.date) + then true + else false + end as last_booking_was_12_months_ago, + case + when + date_trunc('month', hhbf.second_to_last_time_booked_date_utc) + + interval '12 months' + < date_trunc('month', hhbf.last_time_booked_date_utc) + then true + else false + end as had_previous_booking_more_than_12_months_before_the_last + from deal_historic_booking_dates hhbf + left join hubspot_deal_offboardings hdo on hhbf.id_deal = hdo.id_deal + + ) +select + date, + id_deal, + creation_date_utc, + first_time_booked_date_utc, + last_time_booked_date_utc, + second_to_last_time_booked_date_utc, + cancellation_date_utc, + case + -- 01-New: The deal has been created this month and has not had any booking. + -- Additionally, the deal has not been offboarded in hubspot. + when + not deal_has_at_least_one_booking + and deal_was_created_this_month + and not deal_has_been_offboarded + then '01-New' + -- 02-Never Booked: The deal has been created before this month and has not + -- had any booking. Additionally, the deal has not been offboarded in hubspot. + when + not deal_has_at_least_one_booking + and not deal_was_created_this_month + and not deal_has_been_offboarded + then '02-Never Booked' + -- 03-First Time Booked: The deal has been booked for the first time and it + -- has been created this month. Additionally, the deal has not been offboarded + -- in hubspot. + when + deal_has_first_booking + and has_been_booked_within_current_month + and not deal_has_been_offboarded + then '03-First Time Booked' + -- 04-Active: The deal has had at least 1 booking in its history and it's + -- been less than 12 months since the last booking and has not been offboarded + -- in hubspot and is not reactivated and is not FTB + when + deal_has_at_least_one_booking + and has_been_booked_within_last_12_months + and not deal_has_been_offboarded + -- not reactivated + and not ( + had_previous_booking_more_than_12_months_before_the_last + and has_been_booked_within_current_month + ) + -- not FTB + and not (deal_has_first_booking and has_been_booked_within_current_month) + then '04-Active' + -- 05-Churning: The deal has been offboarded this month. Alternatively, The + -- deal has been booked at least once and it's been 12 months since the last + -- booking + when + ( + deal_has_at_least_one_booking + and last_booking_was_12_months_ago + and not deal_has_been_offboarded + ) + or deal_was_offboarded_this_month + then '05-Churning' + -- 06-Inactive: The deal has been offboarded in the past but not this month. + -- Alternatively, the deal is not offboarded and the deal has been booked at + -- least once and it's been more than 12 months since the last booking. + when + ( + deal_has_at_least_one_booking + and not has_been_booked_within_last_12_months + and not last_booking_was_12_months_ago + and not deal_has_been_offboarded + ) + or (deal_has_been_offboarded and not deal_was_offboarded_this_month) + then '06-Inactive' + -- 07-Reactivated: The deal is not offboarded but was churned/inactive, and + -- now has had a new booking this month + when + had_previous_booking_more_than_12_months_before_the_last + and has_been_booked_within_current_month + and not deal_has_been_offboarded + then '07-Reactivated' + else null + end as deal_lifecycle_state, + has_been_booked_within_current_month, + has_been_booked_within_last_6_months, + has_been_booked_within_last_12_months, + deal_has_been_offboarded as has_been_offboarded + +from deal_historic_features diff --git a/models/intermediate/kpis/int_kpis__metric_daily_deals.sql b/models/intermediate/kpis/int_kpis__metric_daily_deals.sql new file mode 100644 index 0000000..e27f6a6 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_daily_deals.sql @@ -0,0 +1,73 @@ +{{ + config( + materialized="table", + unique_key=[ + "date", + "main_billing_country_iso_3_per_deal", + "active_accommodations_per_deal_segmentation", + ], + ) +}} +select + -- Unique Key -- + ldl.date, + -- Dimensions -- + 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, + count( + distinct case + when ldl.deal_lifecycle_state = '01-New' then ldl.id_deal else null + end + ) as new_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '02-Never Booked' then ldl.id_deal else null + end + ) as never_booked_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '03-First Time Booked' + then ldl.id_deal + else null + end + ) as first_time_booked_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '04-Active' then ldl.id_deal else null + end + ) as active_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '05-Churning' then ldl.id_deal else null + end + ) as churning_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '06-Inactive' then ldl.id_deal else null + end + ) as inactive_deals, + count( + distinct case + when ldl.deal_lifecycle_state = '07-Reactivated' then ldl.id_deal else null + end + ) as reactivated_deals, + sum( + case when has_been_booked_within_current_month then 1 else 0 end + ) as deals_booked_in_month, + sum( + case when has_been_booked_within_last_6_months then 1 else 0 end + ) as deals_booked_in_6_months, + sum( + case when has_been_booked_within_last_12_months then 1 else 0 end + ) as deals_booked_in_12_months +from {{ ref("int_kpis__lifecycle_daily_deal") }} as ldl +left join {{ ref("int_core__deal") }} as icd on ldl.id_deal = icd.id_deal +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on ldl.id_deal = icmas.id_deal + and ldl.date = icmas.date +group by 1, 2, 3 diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 6432fd0..96bcb79 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -203,6 +203,129 @@ models: data_type: boolean description: If the listing has had a booking created in the past 12 months. + - name: int_kpis__lifecycle_daily_deal + description: | + This model computes the daily lifecycle of accounts, at deal level. + The information regarding the booking-related time allows for the current status of any + deal regarding its activity. This information is encapsulated in the following columns: + + deal_lifecycle_state: contains one of the following states + - 01-New: Deals that have been created in the current month, without bookings, that are not offboarded. + - 02-Never Booked: Deals that have been created before the current month, without bookings, that are not offboarded. + - 03-First Time Booked: Deals that have been booked for the first time in the current month, that are not offboarded. + - 04-Active: Deals that have booking activity in the past 12 months (that are not FTB nor reactivated), that are not offboarded. + - 05-Churning: Either Deals that are offboarded in that month or Deals that are becoming inactive because of lack of bookings in the past 12 months + - 06-Inactive: Either Deals that have been previously offboarded or Deals that have not had a booking for more than 12 months. + - 07-Reactivated: Deals that have had a booking in the current month that were inactive or churning before, that are not offboarded. + - Finally, if none of the logic applies, which should not happen, null will be set and a dbt alert will raise. + + Since the states of Active, First Time Booked and Reactivated indicate certain booking activity and are + mutually exclusive, the model also provides information of the recency of the bookings by the following + booleans: + - has_been_booked_within_current_month: If a deal has had a booking created in the current month + - has_been_booked_within_last_6_months: If a deal has had a booking created in the past 6 months + - has_been_booked_within_last_12_months: If a deal has had a booking created in the past 12 months + Note that if a deal has had a booking created in a given month, all 3 columns will be true. Similarly, + if the last booking created to a deal was 5 months ago, only the column has_been_booked_in_1_month + will be false; while the other 2 will be true. + Some final considerations: + - It's possible but not common that a Deal gets offboarded on the same month that has had some bookings created. + - It shouldn't happen that a Deal that is Inactive has some bookings created. However, there's few cases in which + this happens likely because of misconfiguration between Hubspot and Core. This should be reported to increase + data quality. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - id_deal + + columns: + - name: date + data_type: date + description: Date in which a Deal has a given lifecycle state. + tests: + - not_null + + - name: id_deal + data_type: character varying + description: Unique identifier of the Account. + tests: + - not_null + + - name: creation_date_utc + data_type: date + description: Date of when the first host associated to that deal was created. + + - name: first_time_booked_date_utc + data_type: date + description: | + Date of the first booking created for a given deal. Can be null if the deal + has never had a booking associated with it. + + - name: last_time_booked_date_utc + data_type: date + description: | + Date of the last booking created for a given deal. Can be null if the deal + has never had a booking associated with it. Can be the same as first_time_booked_date_utc + if the deal only had 1 booking in its history. + + - name: second_to_last_time_booked_date_utc + data_type: date + description: | + Date of the second-to-last booking created for a given deal, meaning the creation + date of the booking that precedes the last one. It's relevant for the reactivation computation + on the lifecycle. Can be null if the deal has never had a booking associated with it or if + the deal only had 1 booking in its history. + + - name: cancellation_date_utc + data_type: date + description: | + Date of when the deal was cancelled, according to Hubspot. This is the date we're considering + for hard offboarding. It can be null, meaning the account has not been offboarded. + + - name: deal_lifecycle_state + data_type: character varying + description: | + Contains the lifecycle state of a deal. The accepted values are: + 01-New, 02-Never Booked, 03-First Time Booked, 04-Active, 05-Churning, 06-Inactive, + 07-Reactivated. Failing to implement the logic will result in alert. + tests: + - not_null + - accepted_values: + values: + - 01-New + - 02-Never Booked + - 03-First Time Booked + - 04-Active + - 05-Churning + - 06-Inactive + - 07-Reactivated + + - name: has_been_booked_within_current_month + data_type: boolean + description: | + If the deal has had a booking already created in the current month. + Note that if the Booking is created on the 5th day, this column will + be false for the days 1st to 4th, and true from the day 5th onwards. + + - name: has_been_booked_within_last_6_months + data_type: boolean + description: | + If the deal has had a booking created in the past 6 months. + + - name: has_been_booked_within_last_12_months + data_type: boolean + description: | + If the deal has had a booking created in the past 12 months. + + - name: has_been_offboarded + data_type: boolean + description: | + If the deal has been cancelled or not. Note that if the Deal + has been offboarded on the 5th day, this column will be false + for the days 1st to 4th, and true from the day 5th onwards. + - name: int_kpis__dimension_daily_accommodation description: | This model computes the deal segmentation per number of @@ -4957,3 +5080,243 @@ models: description: | The month-to-date Waiver Amount Paid Back to Hosts, in GBP, without taxes for a given date, dimension and value. + + - name: int_kpis__metric_daily_deals + description: | + This model computes the Daily Deal metrics at the deepest granularity. + + Be aware that this Deal entity will differ from how the rest of models + usually operate. This is because we compute Deal metrics, thus it does + not make sense to compute these at Deal level. + + Also, Deal metrics at daily level already contain the time dimension + aggregates needed, thus we won't have mtd or monthly equivalent models, + but rather just select from this daily model the needed days to recover + the necessary information. + + The unique key corresponds to the deepest granularity of the model, + in this case: + - date, + - main_billing_country_iso_3_per_deal, + - active_accommodations_per_deal_segmentation + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - main_billing_country_iso_3_per_deal + - active_accommodations_per_deal_segmentation + + columns: + - name: date + data_type: date + description: Date containing the Deal metrics. + tests: + - not_null + + - name: active_accommodations_per_deal_segmentation + data_type: string + description: | + Segment value based on the number of listings booked in 12 months + for a given deal and date. + tests: + - not_null + - accepted_values: + values: + - "0" + - "01-05" + - "06-20" + - "21-60" + - "61+" + - "UNSET" + + - name: main_billing_country_iso_3_per_deal + data_type: string + description: | + Main billing country of the host aggregated at Deal level. + tests: + - not_null + + - name: new_deals + data_type: bigint + description: | + Count of new deals in a given date and per specified dimension. + + - name: never_booked_deals + data_type: bigint + description: | + Count of never booked deals in a given date and per specified dimension. + + - name: first_time_booked_deals + data_type: bigint + description: | + Count of first-time booked deals in a given date and per specified dimension. + + - name: active_deals + data_type: bigint + description: | + Count of active deals in a given date and per specified dimension. + + - name: inactive_deals + data_type: bigint + description: | + Count of inactive deals in a given date and per specified dimension. + + - name: churning_deals + data_type: bigint + description: | + Count of churning deals in a given date and per specified dimension. + + - name: reactivated_deals + data_type: bigint + description: | + Count of reactivated deals in a given date and per specified dimension. + + - name: deals_booked_in_month + data_type: bigint + description: | + Count of deals booked within the month in a given date and per specified dimension. + + - name: deals_booked_in_6_months + data_type: bigint + description: | + Count of deals booked within the past 6 months in a given date and per specified dimension. + + - name: deals_booked_in_12_months + data_type: bigint + description: | + Count of deals booked within the past 12 months in a given date and per specified dimension. + + - name: int_kpis__agg_daily_deals + description: | + This model computes the dimension aggregation for + Daily Deal metrics. + + The primary key of this model is date, dimension + and dimension_value. + + Be aware that this Deal entity will differ from how the rest of models + usually operate. This is because we compute Deal metrics, thus it does + not make sense to compute these at Deal level. + + Also, Deal metrics at daily level already contain the time dimension + aggregates needed, thus we won't have mtd or monthly equivalent models, + but rather just select from this daily model the needed days to recover + the necessary information. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - dimension + - dimension_value + + columns: + - name: date + data_type: date + description: Date containing the Deal metrics. + tests: + - not_null + + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. + tests: + - assert_dimension_completeness: + metric_column_names: + - new_deals + - never_booked_deals + - first_time_booked_deals + - active_deals + - churning_deals + - inactive_deals + - reactivated_deals + - deals_booked_in_month + - deals_booked_in_6_months + - deals_booked_in_12_months + + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: is_end_of_month + data_type: boolean + description: True if it's end of month, false otherwise. + tests: + - not_null + + - name: is_current_month + data_type: boolean + description: | + True if the date is within the current month, false otherwise. + tests: + - not_null + + - name: is_month_to_date + data_type: boolean + description: | + True if the date is within the scope of month-to-date, false otherwise. + The scope of month-to-date takes into account both 1) a date being in + the current month or 2) a date corresponding to the same month of the + previous year, which day number cannot be higher than yesterday's day + number. + tests: + - not_null + + - name: new_deals + data_type: bigint + description: | + Count of new deals for a given date, dimension and value. + + - name: never_booked_deals + data_type: bigint + description: | + Count of never booked deals for a given date, dimension and value. + + - name: first_time_booked_deals + data_type: bigint + description: | + Count of first-time booked deals for a given date, dimension and value. + + - name: active_deals + data_type: bigint + description: | + Count of active deals for a given date, dimension and value. + + - name: inactive_deals + data_type: bigint + description: | + Count of inactive deals for a given date, dimension and value. + + - name: churning_deals + data_type: bigint + description: | + Count of churning deals for a given date, dimension and value. + + - name: reactivated_deals + data_type: bigint + description: | + Count of reactivated deals for a given date, dimension and value. + + - name: deals_booked_in_month + data_type: bigint + description: | + Count of deals booked within the month for a given date, dimension and value. + + - name: deals_booked_in_6_months + data_type: bigint + description: | + Count of deals booked within the past 6 months for a given date, dimension and value. + + - name: deals_booked_in_12_months + data_type: bigint + description: | + Count of deals booked within the past 12 months for a given date, dimension and value. diff --git a/tests/tmp_kpis_refactor_equivalent_deals.sql b/tests/tmp_kpis_refactor_equivalent_deals.sql new file mode 100644 index 0000000..87683c0 --- /dev/null +++ b/tests/tmp_kpis_refactor_equivalent_deals.sql @@ -0,0 +1,120 @@ +{% set min_date = "2022-01-01" %} +{% set dimensions = ("global", "by_billing_country") %} +-- "by_number_of_listings" excluded on purpose - there's differences because of daily +-- segmentation +with + new_deals as ( + select + date, + dimension, + dimension_value, + new_deals, + never_booked_deals, + first_time_booked_deals, + active_deals, + churning_deals, + inactive_deals, + reactivated_deals, + deals_booked_in_month, + deals_booked_in_6_months, + deals_booked_in_12_months + from {{ ref("int_kpis__agg_daily_deals") }} + where + date >= '{{ min_date }}' + and dimension in {{ dimensions }} + and dimension_value <> 'UNSET' + and (is_end_of_month = true or is_month_to_date = true) + ), + old_deals as ( + select + date, + dimension, + dimension_value, + new_deals, + never_booked_deals, + first_time_booked_deals, + active_deals, + churning_deals, + inactive_deals, + reactivated_deals, + deals_booked_in_month, + deals_booked_in_6_months, + deals_booked_in_12_months + from {{ ref("int_mtd_deal_metrics") }} + where date >= '{{ min_date }}' and dimension in {{ dimensions }} + ), + comparison as ( + select + coalesce(o.date, n.date) as date, + coalesce(o.dimension, n.dimension) as dimension, + coalesce(o.dimension_value, n.dimension_value) as dimension_value, + o.new_deals as old_new_deals, + n.new_deals as new_new_deals, + coalesce(o.new_deals, 0) - coalesce(n.new_deals, 0) as diff_new_deals, + + o.never_booked_deals as old_never_booked_deals, + n.never_booked_deals as new_never_booked_deals, + coalesce(o.never_booked_deals, 0) + - coalesce(n.never_booked_deals, 0) as diff_never_booked_deals, + + o.first_time_booked_deals as old_first_time_booked_deals, + n.first_time_booked_deals as new_first_time_booked_deals, + coalesce(o.first_time_booked_deals, 0) + - coalesce(n.first_time_booked_deals, 0) as diff_first_time_booked_deals, + + o.active_deals as old_active_deals, + n.active_deals as new_active_deals, + coalesce(o.active_deals, 0) + - coalesce(n.active_deals, 0) as diff_active_deals, + + o.inactive_deals as old_inactive_deals, + n.inactive_deals as new_inactive_deals, + coalesce(o.inactive_deals, 0) + - coalesce(n.inactive_deals, 0) as diff_inactive_deals, + + o.churning_deals as old_churning_deals, + n.churning_deals as new_churning_deals, + coalesce(o.churning_deals, 0) + - coalesce(n.churning_deals, 0) as diff_churning_deals, + + o.reactivated_deals as old_reactivated_deals, + n.reactivated_deals as new_reactivated_deals, + coalesce(o.reactivated_deals, 0) + - coalesce(n.reactivated_deals, 0) as diff_reactivated_deals, + + o.deals_booked_in_month as old_deals_booked_in_month, + n.deals_booked_in_month as new_deals_booked_in_month, + coalesce(o.deals_booked_in_month, 0) + - coalesce(n.deals_booked_in_month, 0) as diff_deals_booked_in_month, + + o.deals_booked_in_6_months as old_deals_booked_in_6_months, + n.deals_booked_in_6_months as new_deals_booked_in_6_months, + coalesce(o.deals_booked_in_6_months, 0) + - coalesce(n.deals_booked_in_6_months, 0) as diff_deals_booked_in_6_months, + + o.deals_booked_in_12_months as old_deals_booked_in_12_months, + n.deals_booked_in_12_months as new_deals_booked_in_12_months, + coalesce(o.deals_booked_in_12_months, 0) + - coalesce(n.deals_booked_in_12_months, 0) as diff_deals_booked_in_12_months + + from old_deals o + full outer join + new_deals n + on o.date = n.date + and o.dimension = n.dimension + and o.dimension_value = n.dimension_value + ) +select * +from comparison +where + diff_new_deals <> 0 + or diff_never_booked_deals <> 0 + or diff_first_time_booked_deals <> 0 + or diff_active_deals <> 0 + or diff_inactive_deals <> 0 + or diff_churning_deals <> 0 + or diff_reactivated_deals <> 0 + or diff_deals_booked_in_month <> 0 + or diff_deals_booked_in_6_months <> 0 + or diff_deals_booked_in_12_months <> 0 +order by date desc