From 17f2e92ddc504897cf3eb3865ef9ea44e058cf93 Mon Sep 17 00:00:00 2001 From: uri Date: Mon, 17 Jun 2024 11:10:13 +0200 Subject: [PATCH] Adding guest journey KPIs. Updating gitignore --- .gitignore | 1 + .../core/int_core__mtd_aggregated_metrics.sql | 29 ++++-- .../int_core__mtd_guest_journey_metrics.sql | 99 +++++++++++++++++++ 3 files changed, 119 insertions(+), 10 deletions(-) create mode 100644 models/intermediate/core/int_core__mtd_guest_journey_metrics.sql diff --git a/.gitignore b/.gitignore index 377690d..539b626 100644 --- a/.gitignore +++ b/.gitignore @@ -4,3 +4,4 @@ dbt_packages/ logs/ venv/ *.dump +package-lock.yml \ No newline at end of file diff --git a/models/intermediate/core/int_core__mtd_aggregated_metrics.sql b/models/intermediate/core/int_core__mtd_aggregated_metrics.sql index bcce539..f4277f9 100644 --- a/models/intermediate/core/int_core__mtd_aggregated_metrics.sql +++ b/models/intermediate/core/int_core__mtd_aggregated_metrics.sql @@ -1,17 +1,26 @@ {% set metrics = [ - {'order_by': 1, 'metric': 'Created Bookings', 'value': 'created_bookings', 'previous_year_value': 'previous_year_created_bookings', 'relative_increment': 'relative_increment_created_bookings'}, - {'order_by': 2, 'metric': 'Checkout Bookings', 'value': 'check_out_bookings', 'previous_year_value': 'previous_year_check_out_bookings', 'relative_increment': 'relative_increment_check_out_bookings'}, - {'order_by': 3, 'metric': 'Listings Booked in Month', 'value': 'listings_booked_in_month', 'previous_year_value': 'previous_year_listings_booked_in_month', 'relative_increment': 'relative_increment_listings_booked_in_month'}, - {'order_by': 4, 'metric': 'Listings Booked in 6 Months', 'value': 'listings_booked_in_6_months', 'previous_year_value': 'previous_year_listings_booked_in_6_months', 'relative_increment': 'relative_increment_listings_booked_in_6_months'}, - {'order_by': 5, 'metric': 'Listings Booked in 12 Months', 'value': 'listings_booked_in_12_months', 'previous_year_value': 'previous_year_listings_booked_in_12_months', 'relative_increment': 'relative_increment_listings_booked_in_12_months'}, - {'order_by': 6, 'metric': 'Hosts Booked in Month', 'value': 'hosts_booked_in_month', 'previous_year_value': 'previous_year_hosts_booked_in_month', 'relative_increment': 'relative_increment_hosts_booked_in_month'}, - {'order_by': 7, 'metric': 'Hosts Booked in 6 Months', 'value': 'hosts_booked_in_6_months', 'previous_year_value': 'previous_year_hosts_booked_in_6_months', 'relative_increment': 'relative_increment_hosts_booked_in_6_months'}, - {'order_by': 8, 'metric': 'Hosts Booked in 12 Months', 'value': 'hosts_booked_in_12_months', 'previous_year_value': 'previous_year_hosts_booked_in_12_months', 'relative_increment': 'relative_increment_hosts_booked_in_12_months'} -] %} + {'source': 'int_core__mtd_booking_metrics', 'order_by': 1, 'metric': 'Created Bookings', 'value': 'created_bookings', 'previous_year_value': 'previous_year_created_bookings', 'relative_increment': 'relative_increment_created_bookings'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 2, 'metric': 'Checkout Bookings', 'value': 'check_out_bookings', 'previous_year_value': 'previous_year_check_out_bookings', 'relative_increment': 'relative_increment_check_out_bookings'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 3, 'metric': 'Listings Booked in Month', 'value': 'listings_booked_in_month', 'previous_year_value': 'previous_year_listings_booked_in_month', 'relative_increment': 'relative_increment_listings_booked_in_month'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 4, 'metric': 'Listings Booked in 6 Months', 'value': 'listings_booked_in_6_months', 'previous_year_value': 'previous_year_listings_booked_in_6_months', 'relative_increment': 'relative_increment_listings_booked_in_6_months'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 5, 'metric': 'Listings Booked in 12 Months', 'value': 'listings_booked_in_12_months', 'previous_year_value': 'previous_year_listings_booked_in_12_months', 'relative_increment': 'relative_increment_listings_booked_in_12_months'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 6, 'metric': 'Hosts Booked in Month', 'value': 'hosts_booked_in_month', 'previous_year_value': 'previous_year_hosts_booked_in_month', 'relative_increment': 'relative_increment_hosts_booked_in_month'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 7, 'metric': 'Hosts Booked in 6 Months', 'value': 'hosts_booked_in_6_months', 'previous_year_value': 'previous_year_hosts_booked_in_6_months', 'relative_increment': 'relative_increment_hosts_booked_in_6_months'}, + {'source': 'int_core__mtd_booking_metrics', 'order_by': 8, 'metric': 'Hosts Booked in 12 Months', 'value': 'hosts_booked_in_12_months', 'previous_year_value': 'previous_year_hosts_booked_in_12_months', 'relative_increment': 'relative_increment_hosts_booked_in_12_months'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 9, 'metric': 'Guest Journey Created', 'value': 'created_guest_journeys', 'previous_year_value': 'previous_year_created_guest_journeys', 'relative_increment': 'relative_increment_created_guest_journeys'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 10, 'metric': 'Guest Journey Started', 'value': 'started_guest_journeys', 'previous_year_value': 'previous_year_started_guest_journeys', 'relative_increment': 'relative_increment_started_guest_journeys'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 11, 'metric': 'Guest Journey Completed', 'value': 'completed_guest_journeys', 'previous_year_value': 'previous_year_completed_guest_journeys', 'relative_increment': 'relative_increment_completed_guest_journeys'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 12, 'metric': 'Guest Journey Start Rate', 'value': 'start_rate_guest_journey', 'previous_year_value': 'previous_year_start_rate_guest_journey', 'relative_increment': 'relative_increment_start_rate_guest_journey'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 13, 'metric': 'Guest Journey Completion Rate', 'value': 'completion_rate_guest_journey', 'previous_year_value': 'previous_year_completion_rate_guest_journey', 'relative_increment': 'relative_increment_completion_rate_guest_journey'}, + {'source': 'int_core__mtd_guest_journey_metrics', 'order_by': 14, 'metric': 'Guest Journey Incompletion Rate', 'value': 'incompletion_rate_guest_journey', 'previous_year_value': 'previous_year_incompletion_rate_guest_journey', 'relative_increment': 'relative_increment_incompletion_rate_guest_journey'} +] %} with int_core__mtd_booking_metrics as ( select * from {{ ref("int_core__mtd_booking_metrics") }} + ), + int_core__mtd_guest_journey_metrics as ( + select * from {{ ref("int_core__mtd_guest_journey_metrics") }} ) {% for metric in metrics %} select @@ -27,6 +36,6 @@ select {{ metric.value }} as value, {{ metric.previous_year_value }} as previous_year_value, {{ metric.relative_increment }} as relative_increment -from int_core__mtd_booking_metrics +from {{ metric.source }} {% if not loop.last %}union all{% endif %} {% endfor %} diff --git a/models/intermediate/core/int_core__mtd_guest_journey_metrics.sql b/models/intermediate/core/int_core__mtd_guest_journey_metrics.sql new file mode 100644 index 0000000..f653c6c --- /dev/null +++ b/models/intermediate/core/int_core__mtd_guest_journey_metrics.sql @@ -0,0 +1,99 @@ +/* +This model provides Month-To-Date (MTD) based on Guest Journey metrics. + +*/ +{{ config(materialized="table", unique_key="date") }} +with + int_core__verification_requests as (select * from {{ ref("int_core__verification_requests") }}), + int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), + + -- Created Guest Journeys MTD -- + created_year_month as ( + select d.date, count(distinct vr.id_verification_request) as created_guest_journeys + from int_dates_mtd d + inner join + int_core__verification_requests vr + on extract(year from vr.created_date_utc) = d.year + and extract(month from vr.created_date_utc) = d.month + and extract(day from vr.created_date_utc) <= d.day + group by 1 + ), + -- Started Guest Journeys MTD -- + started_year_month as ( + select d.date, count(distinct vr.id_verification_request) as started_guest_journeys + from int_dates_mtd d + inner join + int_core__verification_requests vr + on extract(year from vr.verification_estimated_started_date_utc) = d.year + and extract(month from vr.verification_estimated_started_date_utc) = d.month + and extract(day from vr.verification_estimated_started_date_utc) <= d.day + group by 1 + ), + -- Completed Guest Journeys MTD -- + completed_year_month as ( + select d.date, count(distinct vr.id_verification_request) as completed_guest_journeys + from int_dates_mtd d + inner join + int_core__verification_requests vr + on extract(year from vr.verification_estimated_completed_date_utc) = d.year + and extract(month from vr.verification_estimated_completed_date_utc) = d.month + and extract(day from vr.verification_estimated_completed_date_utc) <= d.day + group by 1 + ), + -- Final aggregation of subqueries + rates computation -- + main_kpi as ( + select + d.year, + d.month, + d.day, + d.date, + d.is_end_of_month, + d.is_current_month, + cym.created_guest_journeys, + sym.started_guest_journeys, + coym.completed_guest_journeys, + cast(sym.started_guest_journeys as decimal)/cym.created_guest_journeys as start_rate_guest_journey, + cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as completion_rate_guest_journey, + 1-cast(coym.completed_guest_journeys as decimal)/sym.started_guest_journeys as incompletion_rate_guest_journey + from int_dates_mtd d + left join created_year_month cym on d.date = cym.date + left join started_year_month sym on d.date = sym.date + left join completed_year_month coym on d.date = coym.date + ) +-- Pivoting to get previous year for each line & computing relative increment +-- (rel_incr) -- +select + a.year, + a.month, + a.day, + a.is_end_of_month, + a.is_current_month, + a.date, + b.date as previous_year_date, + a.created_guest_journeys, + b.created_guest_journeys as previous_year_created_guest_journeys, + cast(a.created_guest_journeys as decimal) / b.created_guest_journeys + - 1 as relative_increment_created_guest_journeys, + a.started_guest_journeys, + b.started_guest_journeys as previous_year_started_guest_journeys, + cast(a.started_guest_journeys as decimal) / b.started_guest_journeys + - 1 as relative_increment_started_guest_journeys, + a.completed_guest_journeys, + b.completed_guest_journeys as previous_year_completed_guest_journeys, + cast(a.completed_guest_journeys as decimal) / b.completed_guest_journeys + - 1 as relative_increment_completed_guest_journeys, + a.start_rate_guest_journey, + b.start_rate_guest_journey as previous_year_start_rate_guest_journey, + cast(a.start_rate_guest_journey as decimal) / b.start_rate_guest_journey + - 1 as relative_increment_start_rate_guest_journey, + a.completion_rate_guest_journey, + b.completion_rate_guest_journey as previous_year_completion_rate_guest_journey, + cast(a.completion_rate_guest_journey as decimal) / b.completion_rate_guest_journey + - 1 as relative_increment_completion_rate_guest_journey, + a.incompletion_rate_guest_journey, + b.incompletion_rate_guest_journey as previous_year_incompletion_rate_guest_journey, + cast(a.incompletion_rate_guest_journey as decimal) / b.incompletion_rate_guest_journey + - 1 as relative_increment_incompletion_rate_guest_journey +from main_kpi a +left join main_kpi b on a.month = b.month and a.year = b.year + 1 +where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day)) \ No newline at end of file