Merged PR 2172: Adding accommodation metrics by deal id

Adding accommodation metrics by deal id with the model `int_core__monthly_accommodation_history_by_deal`.

With this PR, we have the full set of batch 1 metrics by deal id completed, although separated in different tables. Aggregation will come in a separated PR.

Similarly as the previous PR, this one it's a mix between the logic of `int_core__mtd_accommodation_metrics` and the logic existing for the `int_core__monthly_X_history_by_deal` . It also adds the tests in schema.

Related work items: #17689
This commit is contained in:
Oriol Roqué Paniagua 2024-07-02 09:32:52 +00:00
parent 1a4b6b4c14
commit f9741d6f69
2 changed files with 77 additions and 0 deletions

View file

@ -0,0 +1,52 @@
/*
This model provides monthly accommodation metrics for those hosts that have a deal assigned.
*/
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
with
int_core__mtd_accommodation_lifecycle as (select * from {{ ref("int_core__mtd_accommodation_lifecycle") }}),
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
int_core__unique_accommodation_to_user as (select * from {{ ref("int_core__unique_accommodation_to_user") }}),
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
listings_metric_aggregation_per_date_and_deal as (
select
al.date,
u.id_deal,
COUNT(distinct case when al.accommodation_lifecycle_state = '01-New' then al.id_accommodation else null end) as new_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '02-Never Booked' then al.id_accommodation else null end) as never_booked_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '03-First Time Booked' then al.id_accommodation else null end) as first_time_booked_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '04-Active' then al.id_accommodation else null end) as active_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '05-Churning' then al.id_accommodation else null end) as churning_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '06-Inactive' then al.id_accommodation else null end) as inactive_listings,
COUNT(distinct case when al.accommodation_lifecycle_state = '07-Reactivated' then al.id_accommodation else null end) as reactivated_listings,
SUM(case when has_been_booked_within_current_month then 1 else 0 end) as listings_booked_in_month,
SUM(case when has_been_booked_within_last_6_months then 1 else 0 end) as listings_booked_in_6_months,
SUM(case when has_been_booked_within_last_12_months then 1 else 0 end) as listings_booked_in_12_months
from int_core__mtd_accommodation_lifecycle al
inner join int_core__unique_accommodation_to_user atu
on al.id_accommodation = atu.id_accommodation
inner join int_core__unified_user u
on atu.id_user_owner = u.id_user
where id_deal is not null
group by al.date, u.id_deal
)
select
d.year,
d.month,
d.day,
d.date,
d.id_deal,
l.new_listings as new_listings,
l.never_booked_listings as never_booked_listings,
l.first_time_booked_listings as first_time_booked_listings,
l.active_listings as active_listings,
l.churning_listings as churning_listings,
l.inactive_listings as inactive_listings,
l.reactivated_listings as reactivated_listings,
l.listings_booked_in_month as listings_booked_in_month,
l.listings_booked_in_6_months as listings_booked_in_6_months,
l.listings_booked_in_12_months as listings_booked_in_12_months
from int_dates_by_deal d
left join listings_metric_aggregation_per_date_and_deal l
on d.date = l.date and d.id_deal = l.id_deal

View file

@ -143,6 +143,31 @@ models:
- not_null
- unique
- name: int_core__monthly_accommodation_history_by_deal
description: |
This model contains the historic information regarding the accommodations, also known
as listings, for each deal id. It's used for the business KPIs in the view by deal id.
Data is aggregated at the last day of the month, or up to yesterday if it's the
current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic listing metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null
- name: int_core__monthly_booking_history_by_deal
description: |
This model contains the historic information regarding the bookings for each deal id.