From 771b22688837d23e362089dda82133f2c2cc4d71 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Tue, 18 Jun 2024 14:58:55 +0000 Subject: [PATCH] Merged PR 2068: Adding cancelled bookings metric Adding cancelled bookings metric based on the feedback of the tech team. Mainly, the date of a cancelled booking can be considered as the `updated_date_utc` for those bookings with status cancelled, as it's a terminal state and no additional steps should follow. I also took the opportunity to update: - The order on the `int_core__mtd_aggregated_metrics`, so it matches the one in the Notion page for the 1st batch, freeing already the space for the order_by numbers for missing metrics - Make acronyms of alias in the `main_kpi` subquery in `int_core__mtd_booking_metrics` slightly more clear - Remove empty line at the end of the file in `int_core__mtd_booking_metrics` Keep in mind that the cancelled bookings metric will be directly available in the dashboard once this PR is approved and DWH re-runs. Related work items: #17310 --- .../core/int_core__mtd_aggregated_metrics.sql | 131 ++++++++++-------- .../core/int_core__mtd_booking_metrics.sql | 29 +++- 2 files changed, 93 insertions(+), 67 deletions(-) diff --git a/models/intermediate/core/int_core__mtd_aggregated_metrics.sql b/models/intermediate/core/int_core__mtd_aggregated_metrics.sql index 2188e7a..735f94a 100644 --- a/models/intermediate/core/int_core__mtd_aggregated_metrics.sql +++ b/models/intermediate/core/int_core__mtd_aggregated_metrics.sql @@ -11,69 +11,24 @@ { "source": "int_core__mtd_booking_metrics", "order_by": 2, + "metric": "Cancelled Bookings", + "value": "cancelled_bookings", + "previous_year_value": "previous_year_cancelled_bookings", + "relative_increment": "relative_increment_cancelled_bookings", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 3, "metric": "Checkout Bookings", "value": "check_out_bookings", "previous_year_value": "previous_year_check_out_bookings", "relative_increment": "relative_increment_check_out_bookings", "number_format": "integer", }, - { - "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", - "number_format": "integer", - }, - { - "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", - "number_format": "integer", - }, - { - "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", - "number_format": "integer", - }, - { - "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", - "number_format": "integer", - }, - { - "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", - "number_format": "integer", - }, - { - "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", - "number_format": "integer", - }, - { + { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 9, + "order_by": 4, "metric": "Guest Journey Created", "value": "created_guest_journeys", "previous_year_value": "previous_year_created_guest_journeys", @@ -82,7 +37,7 @@ }, { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 10, + "order_by": 5, "metric": "Guest Journey Started", "value": "started_guest_journeys", "previous_year_value": "previous_year_started_guest_journeys", @@ -91,16 +46,70 @@ }, { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 11, + "order_by": 6, "metric": "Guest Journey Completed", "value": "completed_guest_journeys", "previous_year_value": "previous_year_completed_guest_journeys", "relative_increment": "relative_increment_completed_guest_journeys", "number_format": "integer", }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 9, + "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", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 10, + "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", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 11, + "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", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 15, + "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", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 16, + "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", + "number_format": "integer", + }, + { + "source": "int_core__mtd_booking_metrics", + "order_by": 17, + "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", + "number_format": "integer", + }, { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 12, + "order_by": 19, "metric": "Guest Journey Start Rate", "value": "start_rate_guest_journey", "previous_year_value": "previous_year_start_rate_guest_journey", @@ -109,7 +118,7 @@ }, { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 13, + "order_by": 20, "metric": "Guest Journey Completion Rate", "value": "completion_rate_guest_journey", "previous_year_value": "previous_year_completion_rate_guest_journey", @@ -118,7 +127,7 @@ }, { "source": "int_core__mtd_guest_journey_metrics", - "order_by": 14, + "order_by": 21, "metric": "Guest Journey Incompletion Rate", "value": "incompletion_rate_guest_journey", "previous_year_value": "previous_year_incompletion_rate_guest_journey", diff --git a/models/intermediate/core/int_core__mtd_booking_metrics.sql b/models/intermediate/core/int_core__mtd_booking_metrics.sql index a59577a..7784af4 100644 --- a/models/intermediate/core/int_core__mtd_booking_metrics.sql +++ b/models/intermediate/core/int_core__mtd_booking_metrics.sql @@ -1,7 +1,6 @@ /* This model provides Month-To-Date (MTD) based on Booking metrics. -At this stage, we are not filtering out any booking_state (Approved, Cancelled, NotApproved, NoFlags, Flagged, IncompleteInformation, Rejected) */ {{ config(materialized="table", unique_key="date") }} with @@ -30,6 +29,19 @@ with and extract(day from b.check_out_date_utc) <= d.day group by 1 ), + -- Cancelled Bookings MTD -- + -- Cancellation date equivalent to the last time the cancelled booking was updated + cancelled_year_month as ( + select d.date, count(distinct b.id_booking) as cancelled_bookings + from int_dates_mtd d + inner join + int_core__bookings b + on extract(year from b.updated_date_utc) = d.year + and extract(month from b.updated_date_utc) = d.month + and extract(day from b.updated_date_utc) <= d.day + and upper(b.booking_state) = 'CANCELLED' + group by 1 + ), -- Computation of number of months difference for activity-based logic -- creation_month_diff as ( select @@ -126,8 +138,9 @@ with d.date, d.is_end_of_month, d.is_current_month, - cym.created_bookings, + crym.created_bookings, coym.check_out_bookings, + caym.cancelled_bookings, bba.listings_booked_in_month, bba.listings_booked_in_6_months, bba.listings_booked_in_12_months, @@ -141,9 +154,10 @@ with bba.guests_booked_in_12_months, bba.historic_booked_guests from int_dates_mtd d - left join created_year_month cym on cym.date = d.date - left join check_out_year_month coym on d.date = coym.date - left join booking_based_activity bba on d.date = bba.date + left join created_year_month crym on crym.date = d.date + left join check_out_year_month coym on coym.date = d.date + left join cancelled_year_month caym on caym.date = d.date + left join booking_based_activity bba on bba.date = d.date ) -- Pivoting to get previous year for each line & computing relative increment -- (rel_incr) -- @@ -163,6 +177,10 @@ select b.check_out_bookings as previous_year_check_out_bookings, cast(a.check_out_bookings as decimal) / b.check_out_bookings - 1 as relative_increment_check_out_bookings, + a.cancelled_bookings, + b.cancelled_bookings as previous_year_cancelled_bookings, + cast(a.cancelled_bookings as decimal) / b.cancelled_bookings + - 1 as relative_increment_cancelled_bookings, a.listings_booked_in_month, b.listings_booked_in_month as previous_year_listings_booked_in_month, cast(a.listings_booked_in_month as decimal) / b.listings_booked_in_month @@ -214,4 +232,3 @@ select 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)) -