Merge branch 'master' of ssh.dev.azure.com:v3/guardhog/Data/data-dwh-dbt-project
This commit is contained in:
commit
61ceda5234
4 changed files with 25 additions and 47 deletions
|
|
@ -12,23 +12,10 @@ select
|
|||
atpb.id_user_product_bundle,
|
||||
upb.id_user_host,
|
||||
upb.product_bundle_display_name as user_product_bundle_name,
|
||||
atpb.starts_at_utc as original_starts_at_utc,
|
||||
atpb.ends_at_utc as original_ends_at_utc,
|
||||
/*
|
||||
The following is to ensure that we cap the reporting to the
|
||||
dates in which these product bundles could have been active.
|
||||
For analysis and reporting purposes, it is encouraged to use
|
||||
the effective fields (start_date and end_date) rather than the
|
||||
backend ones (named as original_starts_at and original_ends_at).
|
||||
*/
|
||||
greatest(
|
||||
date(atpb.starts_at_utc), upb.effective_start_date_utc
|
||||
) as effective_start_date_utc,
|
||||
case
|
||||
when atpb.has_no_end_date
|
||||
then null
|
||||
else greatest(date(atpb.ends_at_utc), upb.effective_end_date_utc)
|
||||
end as effective_end_date_utc,
|
||||
atpb.starts_at_utc,
|
||||
atpb.ends_at_utc,
|
||||
date(atpb.starts_at_utc) as start_date_utc,
|
||||
date(atpb.ends_at_utc) as end_date_utc,
|
||||
atpb.has_no_end_date,
|
||||
upb.product_bundle_services,
|
||||
upb.is_custom_bundle,
|
||||
|
|
|
|||
|
|
@ -68,11 +68,11 @@ with
|
|||
count(
|
||||
distinct case
|
||||
when
|
||||
atpb.effective_start_date_utc <= current_date
|
||||
and coalesce(
|
||||
atpb.effective_end_date_utc, {{ var("end_of_time") }}
|
||||
atpb.start_date_utc <= current_date
|
||||
and (
|
||||
atpb.end_date_utc >= current_date
|
||||
or atpb.has_no_end_date = true
|
||||
)
|
||||
>= current_date
|
||||
then atpb.id_accommodation
|
||||
else null
|
||||
end
|
||||
|
|
@ -80,11 +80,11 @@ with
|
|||
count(
|
||||
distinct case
|
||||
when
|
||||
atpb.effective_start_date_utc <= current_date
|
||||
and coalesce(
|
||||
atpb.effective_end_date_utc, {{ var("end_of_time") }}
|
||||
atpb.start_date_utc <= current_date
|
||||
and (
|
||||
atpb.end_date_utc >= current_date
|
||||
or atpb.has_no_end_date = true
|
||||
)
|
||||
>= current_date
|
||||
and atpb.user_product_bundle_name
|
||||
not in ({{ var("default_service") }})
|
||||
then atpb.id_accommodation
|
||||
|
|
|
|||
|
|
@ -2183,42 +2183,33 @@ models:
|
|||
description: |
|
||||
The name of the Product Bundle.
|
||||
|
||||
- name: original_starts_at_utc
|
||||
- name: starts_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this Product Bundle is assigned into an Accommodation was
|
||||
active for the first time, according to the Backend.
|
||||
Keep in mind that this timestamp can be before the migration of the user, thus
|
||||
effective_start_date_utc might be better for reporting and analysis purposes.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: original_ends_at_utc
|
||||
- name: ends_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this Product Bundle is assigned into an Accommodation was
|
||||
active for the last time, according to the Backend. If null it means that
|
||||
it's currently active.
|
||||
Keep in mind that this timestamp can be before the migration of the user, thus
|
||||
effective_end_date_utc might be better for reporting and analysis purposes.
|
||||
|
||||
- name: effective_start_date_utc
|
||||
- name: start_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Effective date of when this Product Bundle is assigned into an Accommodation was
|
||||
active for the first time.
|
||||
It takes into account the fact that a User needs to be migrated in order for
|
||||
the Product Bundle to be active in the Accommodation. In case of doubt, use this date.
|
||||
The date when this Product Bundle was first assigned to the Accommodation.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: effective_end_date_utc
|
||||
- name: end_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Effective date of when this Product Bundle is assigned into an Accommodation was
|
||||
active for the last time. If null it means that it's currently active.
|
||||
It takes into account the fact that a User needs to be migrated in order for
|
||||
the Product Bundle to be active in the Accommodation. In case of doubt, use this date.
|
||||
The date when this Product Bundle was last active for the Accommodation.
|
||||
If null, it means the Product Bundle is currently active.
|
||||
|
||||
- name: has_no_end_date
|
||||
data_type: boolean
|
||||
|
|
|
|||
|
|
@ -16,11 +16,11 @@ with
|
|||
select
|
||||
*,
|
||||
row_number() over (
|
||||
partition by id_accommodation, effective_start_date_utc
|
||||
partition by id_accommodation, start_date_utc
|
||||
order by
|
||||
effective_start_date_utc desc, -- Prefers the latest effective start date
|
||||
original_starts_at_utc desc, -- In case of ties, prefers the most recent original start
|
||||
coalesce(original_ends_at_utc, {{ var("end_of_time") }}) desc
|
||||
start_date_utc desc, -- Prefers the latest starting date
|
||||
starts_at_utc desc, -- In case of ties, prefers the most recent starting time
|
||||
coalesce(ends_at_utc, {{ var("end_of_time") }}) desc
|
||||
) as rn
|
||||
from {{ ref("int_core__accommodation_to_product_bundle") }}
|
||||
)
|
||||
|
|
@ -51,8 +51,8 @@ inner join
|
|||
inner join
|
||||
latest_daily_bundle as ldb
|
||||
on bs.id_user_product_bundle = ldb.id_user_product_bundle
|
||||
and date >= ldb.effective_start_date_utc
|
||||
and date < coalesce(ldb.effective_end_date_utc, {{ var("end_of_time") }})
|
||||
and date >= ldb.start_date_utc
|
||||
and (date < ldb.end_date_utc or ldb.has_no_end_date = true)
|
||||
and ldb.rn = 1
|
||||
left join
|
||||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue