Adding booking services status

This commit is contained in:
Joaquin Ossa 2025-02-13 14:45:26 +01:00
parent 5382a9b32b
commit 43742355f0
2 changed files with 74 additions and 69 deletions

View file

@ -0,0 +1,28 @@
{% macro count_bookings_by_service_status() %}
{% set service_status_map = {
"PROTECTED": "number_protected_bookings",
"REJECTED": "number_rejected_bookings",
"NOCHECKS": "number_no_checks_bookings",
"NOFLAGS": "number_no_flags_bookings",
"PAID": "number_paid_bookings",
"PENDING": "number_pending_bookings",
"-": "number_unknown_status_bookings",
"PARTIALLY PROTECTED": "number_partially_protected_bookings",
"NOT PROTECTED": "number_not_protected_bookings",
"NOT PAID": "number_not_paid_bookings",
"CONFIRMED": "number_confirmed_bookings",
"FORREVIEW": "number_for_review_bookings",
"FLAGGED": "number_flagged_bookings",
} %}
{% for status, alias in service_status_map.items() %}
count(
distinct case
when upper(ub.service_status) = '{{ status }}'
then (ub.id_booking)
else null
end
) as {{ alias }}
{% if not loop.last %}, {% endif %}
{% endfor %}
{% endmacro %}

View file

@ -13,7 +13,36 @@ with
int_core__booking_to_product_bundle as (
select * from {{ ref("int_core__booking_to_product_bundle") }}
),
int_core__booking_service_detail as (
select * from {{ ref("int_core__booking_service_detail") }}
),
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
expanded_booking_services as (
select distinct
id_booking,
trim(unnested_service) as service_name,
service_status,
case when service_name like '% OR %' then 2 else 1 end as rank
from
int_core__booking_service_detail,
lateral unnest(string_to_array(service_name, ' OR ')) as unnested_service
),
ranked_booking_services as (
select
id_booking,
service_name,
service_status,
rank,
row_number() over (
partition by id_booking, service_name order by rank asc -- Prioritize rank 1 first
) as row_num
from expanded_booking_services
),
unnested_booking_services as (
select id_booking, service_name, service_status
from ranked_booking_services
where row_num = 1
),
bundle_services as (
select
bs.id_user_product_bundle,
@ -88,69 +117,11 @@ with
group by 1
),
bookings as (
select distinct
bs.service_display_name,
count(distinct bpb.id_booking) as number_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("approved_booking_state") }}
then bpb.id_booking
else null
end
) as number_approved_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("cancelled_booking_state") }}
then bpb.id_booking
else null
end
) as number_cancelled_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("flagged_booking_state") }}
then bpb.id_booking
else null
end
) as number_flagged_bookings,
count(
distinct case
when
upper(b.booking_state)
= {{ var("incomplete_information_booking_state") }}
then bpb.id_booking
else null
end
) as number_incomplete_information_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("no_flags_booking_state") }}
then bpb.id_booking
else null
end
) as number_no_flags_bookings,
count(
distinct case
when
upper(b.booking_state) = {{ var("not_approved_booking_state") }}
then bpb.id_booking
else null
end
) as number_not_approved_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("rejected_booking_state") }}
then bpb.id_booking
else null
end
) as number_rejected_bookings
from bundle_services bs
left join
int_core__booking_to_product_bundle bpb
on bpb.id_user_product_bundle = bs.id_user_product_bundle
inner join
int_core__bookings b
on b.id_booking = bpb.id_booking
and b.is_duplicate_booking is false
select
ub.service_name as service_display_name,
count(distinct ub.id_booking) as number_bookings,
{{ count_bookings_by_service_status() }}
from unnested_booking_services ub
group by 1
)
select
@ -164,13 +135,19 @@ select
a.number_active_accommodations,
a.number_inactive_accommodations,
b.number_bookings,
b.number_approved_bookings,
b.number_cancelled_bookings,
b.number_flagged_bookings,
b.number_incomplete_information_bookings,
b.number_protected_bookings,
b.number_rejected_bookings,
b.number_no_checks_bookings,
b.number_no_flags_bookings,
b.number_not_approved_bookings,
b.number_rejected_bookings
b.number_paid_bookings,
b.number_pending_bookings,
b.number_unknown_status_bookings,
b.number_partially_protected_bookings,
b.number_not_protected_bookings,
b.number_not_paid_bookings,
b.number_confirmed_bookings,
b.number_for_review_bookings,
b.number_flagged_bookings
from users u
left join accommodations a on u.service_display_name = a.service_display_name
left join bookings b on u.service_display_name = b.service_display_name