diff --git a/models/intermediate/core/int_core__new_dash_services_usage.sql b/models/intermediate/core/int_core__new_dash_services_usage.sql new file mode 100644 index 0000000..17aba21 --- /dev/null +++ b/models/intermediate/core/int_core__new_dash_services_usage.sql @@ -0,0 +1,93 @@ +with + int_core__user_product_bundle_contains_services as ( + select * from {{ ref("int_core__user_product_bundle_contains_services") }} + ), + int_core__user_host as (select * from {{ ref("int_core__user_host") }}), + int_core__accommodation_to_product_bundle as ( + select * from {{ ref("int_core__accommodation_to_product_bundle") }} + ), + int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}), + int_core__booking_to_product_bundle as ( + select * from {{ ref("int_core__booking_to_product_bundle") }} + ), + int_core__bookings as (select * from {{ ref("int_core__bookings") }}), + users as ( + select distinct + (bs.product_service_name), count(distinct bs.id_user_host) as number_users + from int_core__user_product_bundle_contains_services bs + inner join + int_core__user_host uh + on bs.id_user_host = uh.id_user_host + and uh.is_test_account is false + group by 1 + ), + accommodations as ( + select distinct + (bs.product_service_name), + count(distinct apb.id_accommodation) as number_accommodations, + count( + distinct case when a.is_active then apb.id_accommodation else null end + ) as number_active_accommodations, + count( + distinct case + when a.is_active is false then apb.id_accommodation else null + end + ) as number_inactive_accommodations + from int_core__user_product_bundle_contains_services bs + left join + int_core__accommodation_to_product_bundle apb + on apb.id_user_product_bundle = bs.id_user_product_bundle + and now() between apb.original_starts_at_utc and coalesce( + apb.original_ends_at_utc, '2050-12-31' + ) + left join int_core__accommodation a on apb.id_accommodation = a.id_accommodation + group by 1 + ), + bookings as ( + select distinct + (bs.product_service_name), + count(distinct bpb.id_booking) as number_bookings, + count( + distinct case + when upper(b.booking_state) = 'APPROVED' + then bpb.id_booking + else null + end + ) as number_approved_bookings, + count( + distinct case + when upper(b.booking_state) = 'CANCELLED' + then bpb.id_booking + else null + end + ) as number_cancelled_bookings, + count( + distinct case + when upper(b.booking_state) = 'FLAGGED' + then bpb.id_booking + else null + end + ) as number_flagged_bookings + from int_core__user_product_bundle_contains_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 + group by 1 + ) +select + u.product_service_name, + u.number_users, + a.number_accommodations, + a.number_active_accommodations, + a.number_inactive_accommodations, + b.number_bookings, + b.number_approved_bookings, + b.number_cancelled_bookings, + b.number_flagged_bookings +from users u +left join accommodations a on u.product_service_name = a.product_service_name +left join bookings b on u.product_service_name = b.product_service_name