Merged PR 4825: New_dash_agg_metrics update

# Description

Added deals and listings to New Dash metrics model

# Checklist

- [x] The edited models and dependants run properly with production data.
- [x] The edited models are sufficiently documented.
- [x] The edited models contain PK tests, and I've ran and passed them.
- [x] I have checked for DRY opportunities with other models and docs.
- [ ] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Commit wip test

Related work items: #28640
This commit is contained in:
Joaquin Ossa 2025-03-27 16:57:14 +00:00
commit 14f44e6949
4 changed files with 139 additions and 15 deletions

View file

@ -16,12 +16,56 @@ with
),
int_kpis__agg_monthly_new_dash_chargeable_services as (
select * from {{ ref("int_kpis__agg_monthly_new_dash_chargeable_services") }}
),
int_kpis__agg_daily_new_dash_deals_offered_services as (
select * from {{ ref("int_kpis__agg_daily_new_dash_deals_offered_services") }}
),
int_kpis__agg_weekly_new_dash_deals_offered_services as (
select * from {{ ref("int_kpis__agg_weekly_new_dash_deals_offered_services") }}
),
int_kpis__agg_monthly_new_dash_deals_offered_services as (
select * from {{ ref("int_kpis__agg_monthly_new_dash_deals_offered_services") }}
),
int_kpis__agg_daily_new_dash_accommodation_offered_services as (
select *
from {{ ref("int_kpis__agg_daily_new_dash_accommodation_offered_services") }}
),
int_kpis__agg_weekly_new_dash_accommodation_offered_services as (
select *
from {{ ref("int_kpis__agg_weekly_new_dash_accommodation_offered_services") }}
),
int_kpis__agg_monthly_new_dash_accommodation_offered_services as (
select *
from {{ ref("int_kpis__agg_monthly_new_dash_accommodation_offered_services") }}
),
all_dates as (
select distinct date, dimension, dimension_value
from
(
select date, dimension, dimension_value
from int_kpis__agg_daily_new_dash_created_services
union all
select date, dimension, dimension_value
from int_kpis__agg_daily_new_dash_chargeable_services
union all
select date, dimension, dimension_value
from int_kpis__agg_daily_new_dash_deals_offered_services
union all
select date, dimension, dimension_value
from int_kpis__agg_daily_new_dash_accommodation_offered_services
) combined
)
select
coalesce(created.date, chargeable.date) as date,
d.date,
'daily' as time_granularity,
coalesce(created.dimension, chargeable.dimension) as dimension,
coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value,
d.dimension,
d.dimension_value,
coalesce(
deals.deal_with_offered_service_count, 0
) as deal_with_offered_service_count,
coalesce(
accommodation.accommodation_with_offered_service_count, 0
) as accommodation_with_offered_service_count,
coalesce(created.created_services, 0) as created_services,
coalesce(
created.booking_with_created_services_count, 0
@ -32,18 +76,39 @@ select
) as total_chargeable_amount_in_gbp,
coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings,
coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings
from int_kpis__agg_daily_new_dash_created_services created
full outer join
from all_dates d
left join
int_kpis__agg_daily_new_dash_created_services created
on d.date = created.date
and d.dimension = created.dimension
and d.dimension_value = created.dimension_value
left join
int_kpis__agg_daily_new_dash_chargeable_services chargeable
on created.date = chargeable.date
and created.dimension = chargeable.dimension
and created.dimension_value = chargeable.dimension_value
left join
int_kpis__agg_daily_new_dash_deals_offered_services deals
on created.date = deals.date
and created.dimension = deals.dimension
and created.dimension_value = deals.dimension_value
left join
int_kpis__agg_daily_new_dash_accommodation_offered_services accommodation
on created.date = accommodation.date
and created.dimension = accommodation.dimension
and created.dimension_value = accommodation.dimension_value
union all
select
coalesce(created.end_date, chargeable.end_date) as date,
d.date,
'weekly' as time_granularity,
coalesce(created.dimension, chargeable.dimension) as dimension,
coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value,
d.dimension,
d.dimension_value,
coalesce(
deals.deal_with_offered_service_count, 0
) as deal_with_offered_service_count,
coalesce(
accommodation.accommodation_with_offered_service_count, 0
) as accommodation_with_offered_service_count,
coalesce(created.created_services, 0) as created_services,
coalesce(
created.booking_with_created_services_count, 0
@ -54,18 +119,39 @@ select
) as total_chargeable_amount_in_gbp,
coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings,
coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings
from int_kpis__agg_weekly_new_dash_created_services created
full outer join
from all_dates d
left join
int_kpis__agg_weekly_new_dash_created_services created
on d.date = created.end_date
and d.dimension = created.dimension
and d.dimension_value = created.dimension_value
left join
int_kpis__agg_weekly_new_dash_chargeable_services chargeable
on created.end_date = chargeable.end_date
and created.dimension = chargeable.dimension
and created.dimension_value = chargeable.dimension_value
left join
int_kpis__agg_weekly_new_dash_deals_offered_services deals
on created.end_date = deals.date
and created.dimension = deals.dimension
and created.dimension_value = deals.dimension_value
left join
int_kpis__agg_weekly_new_dash_accommodation_offered_services accommodation
on created.end_date = accommodation.date
and created.dimension = accommodation.dimension
and created.dimension_value = accommodation.dimension_value
union all
select
coalesce(created.end_date, chargeable.end_date) as date,
d.date,
'monthly' as time_granularity,
coalesce(created.dimension, chargeable.dimension) as dimension,
coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value,
d.dimension,
d.dimension_value,
coalesce(
deals.deal_with_offered_service_count, 0
) as deal_with_offered_service_count,
coalesce(
accommodation.accommodation_with_offered_service_count, 0
) as accommodation_with_offered_service_count,
coalesce(created.created_services, 0) as created_services,
coalesce(
created.booking_with_created_services_count, 0
@ -76,9 +162,24 @@ select
) as total_chargeable_amount_in_gbp,
coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings,
coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings
from int_kpis__agg_monthly_new_dash_created_services created
full outer join
from all_dates d
left join
int_kpis__agg_monthly_new_dash_created_services created
on d.date = created.end_date
and d.dimension = created.dimension
and d.dimension_value = created.dimension_value
left join
int_kpis__agg_monthly_new_dash_chargeable_services chargeable
on created.end_date = chargeable.end_date
and created.dimension = chargeable.dimension
and created.dimension_value = chargeable.dimension_value
left join
int_kpis__agg_monthly_new_dash_deals_offered_services deals
on created.end_date = deals.date
and created.dimension = deals.dimension
and created.dimension_value = deals.dimension_value
left join
int_kpis__agg_monthly_new_dash_accommodation_offered_services accommodation
on created.end_date = accommodation.date
and created.dimension = accommodation.dimension
and created.dimension_value = accommodation.dimension_value

View file

@ -6711,6 +6711,16 @@ models:
data_tests:
- not_null
- name: deal_with_offered_service_count
data_type: bigint
description: |
The count of deals with services offered by a given date, dimension and value.
- name: accommodation_with_offered_service_count
data_type: bigint
description: |
The count of accommodations with services offered by a given date, dimension and value.
- name: created_services
data_type: bigint
description: |

View file

@ -8,6 +8,9 @@ select
{{ capitalise_and_remove_underscores("dimension") }} as dimension,
dimension_value as dimension_value,
created_services as created_services,
deal_with_offered_service_count as deal_with_offered_service_count,
accommodation_with_offered_service_count
as accommodation_with_offered_service_count,
booking_with_created_services_count as booking_with_created_services_count,
total_chargeable_services as total_chargeable_services,
total_chargeable_amount_in_gbp as total_chargeable_amount_in_gbp,

View file

@ -317,6 +317,16 @@ models:
The created services for a given time granularity, date or dates range,
dimension and value.
- name: deal_with_offered_service_count
data_type: bigint
description: |
The count of deals with services offered by a given date, dimension and value.
- name: accommodation_with_offered_service_count
data_type: bigint
description: |
The count of accommodations with services offered by a given date, dimension and value.
- name: booking_with_created_services_count
data_type: bigint
description: |