Merged PR 4349: Xero metrics by Business Scope
# Description Changes: * Creation of a deal-based model that contains when a "deal has appeared in new dash". This is tricky because a Deal can still have multiple users, thus it needs to be attributed to a date. I've chosen the first user appearance for the rest of the metrics. * Adaptation of dimension deals in KPIs to include a client type, that indicates if the deal is from APIs or not (Platform, i.e., Dashboard). * Xero metrics by Business Scope. This is the previous "dash source" that I need to change in the previously worked models. I decided to include APIs in the segmentation since in most cases we distinguish old dash from new dash by just "anything that is not in new dash". This is very wrong for invoicing metrics, in which we have APIs. So this actually properly computes a client segmentation by scope. Note that I'll need to handle the monthly/mtd metrics/agg for these 2 metric models (Resolutions + Invoiced revenue) separately. # 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. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #27356
This commit is contained in:
parent
a2c2907817
commit
4867e8f6d0
7 changed files with 151 additions and 13 deletions
|
|
@ -0,0 +1,9 @@
|
|||
with int_core__user_host as (select * from {{ ref("int_core__user_host") }})
|
||||
select
|
||||
id_deal,
|
||||
min(user_in_new_dash_since_date_utc) as min_user_in_new_dash_since_date_utc,
|
||||
max(user_in_new_dash_since_date_utc) as max_user_in_new_dash_since_date_utc,
|
||||
count(id_user_host) as total_new_dash_users
|
||||
from int_core__user_host
|
||||
where is_user_in_new_dash and is_missing_id_deal = false
|
||||
group by 1
|
||||
|
|
@ -5592,3 +5592,34 @@ models:
|
|||
data_type: numeric
|
||||
description: |
|
||||
The service fee charged by Superhog with taxes, in GBP.
|
||||
|
||||
- name: int_core__new_dash_deal_since_date
|
||||
description: |
|
||||
This model contains the deals that correspond to user hosts in New Dash.
|
||||
While not the usual case, it's possible that a deal has more than one user
|
||||
host. Thus this model aims to aggregate the first and last migration or
|
||||
appearances dates for each deal. This is specially useful for KPIs purposes.
|
||||
|
||||
columns:
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: |
|
||||
The unique identifier of the deal that is in New Dash.
|
||||
data_tests:
|
||||
- unique
|
||||
- not_null
|
||||
|
||||
- name: min_user_in_new_dash_since_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
The date when the first user host appeared in New Dash for this deal.
|
||||
|
||||
- name: max_user_in_new_dash_since_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
The date when the last user host appeared in New Dash for this deal.
|
||||
|
||||
- name: total_new_dash_users
|
||||
data_type: bigint
|
||||
description: |
|
||||
The total number of user hosts that have appeared in New Dash for this deal.
|
||||
|
|
|
|||
|
|
@ -3,6 +3,7 @@ with
|
|||
hubspot_deals as (
|
||||
select
|
||||
id_deal,
|
||||
deal_pipeline,
|
||||
deal_name as main_deal_name,
|
||||
live_date_utc as deal_start_date,
|
||||
date_trunc('month', live_date_utc) as deal_start_month,
|
||||
|
|
@ -40,6 +41,9 @@ with
|
|||
coalesce(cd.has_active_pms, false) as has_active_pms,
|
||||
cd.active_pms_list,
|
||||
cd.main_billing_country_iso_3_per_deal,
|
||||
case
|
||||
when upper(hd.deal_pipeline) in ('API SALES') then 'API' else 'PLATFORM'
|
||||
end as client_type,
|
||||
min(
|
||||
coalesce(hd.deal_start_date, cd.deal_start_date)
|
||||
) as effective_deal_start_date_utc,
|
||||
|
|
@ -51,13 +55,14 @@ with
|
|||
min(hd.hubspot_listing_segmentation) as hubspot_listing_segmentation
|
||||
from hubspot_deals hd
|
||||
full outer join core_deals cd on hd.id_deal = cd.id_deal
|
||||
group by 1, 2, 3, 4, 5
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
)
|
||||
select
|
||||
cd.id_deal,
|
||||
cd.main_deal_name,
|
||||
cd.has_active_pms,
|
||||
cd.active_pms_list,
|
||||
cd.client_type,
|
||||
cd.main_billing_country_iso_3_per_deal,
|
||||
cd.effective_deal_start_date_utc,
|
||||
cd.effective_deal_start_month,
|
||||
|
|
|
|||
|
|
@ -1,14 +1,36 @@
|
|||
{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %}
|
||||
{% set relevant_transaction_status = "('AUTHORISED')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
ixbt.transaction_date_utc as date,
|
||||
coalesce(ixc.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when ikdd.client_type = 'API'
|
||||
then 'API'
|
||||
-- We will assume that any host resolution payment happening in the same month
|
||||
-- or after the user has been created in the New Dash is considered as New
|
||||
-- Dash. This might not be 100% accurate, but it's a reasonable assumption.
|
||||
when ikdd.client_type = 'PLATFORM'
|
||||
then
|
||||
case
|
||||
when
|
||||
icnddsd.id_deal is not null
|
||||
and date_trunc('month', ixbt.transaction_date_utc)::date
|
||||
>= date_trunc(
|
||||
'month', icnddsd.min_user_in_new_dash_since_date_utc
|
||||
)::date
|
||||
and ixbt.transaction_date_utc
|
||||
>= date({{ var("new_dash_first_invoicing_date") }})
|
||||
then 'New Dash'
|
||||
else 'Old Dash'
|
||||
end
|
||||
else 'UNSET'
|
||||
end as business_scope,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
ikdd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
) as main_billing_country_iso_3_per_deal,
|
||||
coalesce(
|
||||
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
||||
|
|
@ -23,9 +45,12 @@ inner join
|
|||
and upper(ixbtli.account_name) in {{ resolutions_host_payment_account_name }}
|
||||
and upper(ixbt.transaction_status) in {{ relevant_transaction_status }}
|
||||
left join {{ ref("int_xero__contacts") }} as ixc on ixc.id_contact = ixbt.id_contact
|
||||
left join {{ ref("int_core__deal") }} as icd on ixc.id_deal = icd.id_deal
|
||||
left join {{ ref("int_kpis__dimension_deals") }} as ikdd on ixc.id_deal = ikdd.id_deal
|
||||
left join
|
||||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on ixc.id_deal = icmas.id_deal
|
||||
and ixbt.transaction_date_utc = icmas.date
|
||||
group by 1, 2, 3, 4
|
||||
left join
|
||||
{{ ref("int_core__new_dash_deal_since_date") }} as icnddsd
|
||||
on ixc.id_deal = icnddsd.id_deal
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -1,14 +1,36 @@
|
|||
-- Document Status --
|
||||
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
ixsdm.document_issued_date_utc as date,
|
||||
coalesce(ixsdm.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when ikdd.client_type = 'API'
|
||||
then 'API'
|
||||
-- We will assume that any invoice happening in the same month or after the
|
||||
-- user has been created in the New Dash is considered as New Dash. This might
|
||||
-- not be 100% accurate, but it's a reasonable assumption.
|
||||
when ikdd.client_type = 'PLATFORM'
|
||||
then
|
||||
case
|
||||
when
|
||||
icnddsd.id_deal is not null
|
||||
and date_trunc('month', ixsdm.document_issued_date_utc)::date
|
||||
>= date_trunc(
|
||||
'month', icnddsd.min_user_in_new_dash_since_date_utc
|
||||
)::date
|
||||
and ixsdm.document_issued_date_utc
|
||||
>= date({{ var("new_dash_first_invoicing_date") }})
|
||||
then 'New Dash'
|
||||
else 'Old Dash'
|
||||
end
|
||||
else 'UNSET'
|
||||
end as business_scope,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
ikdd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
) as main_billing_country_iso_3_per_deal,
|
||||
coalesce(
|
||||
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
||||
|
|
@ -97,8 +119,8 @@ select
|
|||
-- New Dash
|
||||
ixsdm.accounting_kpis_aggregation = 'Invoiced Operator Revenue'
|
||||
-- Prior to 1st January 2023 we didn't have the split of Booking
|
||||
-- Fees, Listing Fees and Verification Fees. Everything is considered
|
||||
-- as Other Invoiced Revenue.
|
||||
-- Fees, Listing Fees and Verification Fees. Everything is
|
||||
-- considered as Other Invoiced Revenue.
|
||||
or (
|
||||
ixsdm.accounting_root_aggregation = 'Other Invoiced Revenue'
|
||||
and date_trunc('year', ixsdm.document_issued_date_utc)::date
|
||||
|
|
@ -153,10 +175,13 @@ select
|
|||
end
|
||||
) as xero_guesty_net_fees_in_gbp
|
||||
from {{ ref("int_xero__sales_denom_mart") }} as ixsdm
|
||||
left join {{ ref("int_core__deal") }} as icd on ixsdm.id_deal = icd.id_deal
|
||||
left join {{ ref("int_kpis__dimension_deals") }} as ikdd on ixsdm.id_deal = ikdd.id_deal
|
||||
left join
|
||||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on ixsdm.id_deal = icmas.id_deal
|
||||
and ixsdm.document_issued_date_utc = icmas.date
|
||||
left join
|
||||
{{ ref("int_core__new_dash_deal_since_date") }} as icnddsd
|
||||
on ixsdm.id_deal = icnddsd.id_deal
|
||||
where upper(ixsdm.document_status) in {{ relevant_document_statuses }}
|
||||
group by 1, 2, 3, 4
|
||||
group by 1, 2, 3, 4, 5
|
||||
|
|
|
|||
|
|
@ -459,6 +459,16 @@ models:
|
|||
description: |
|
||||
Name of the active PMS associated with the deal. It can have more than
|
||||
one PMS associated with it. It can be null if it doesn't have any PMS associated.
|
||||
- name: client_type
|
||||
data_type: string
|
||||
description: |
|
||||
Type of client associated with the deal.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- API
|
||||
- PLATFORM
|
||||
- name: main_billing_country_iso_3_per_deal
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -3660,13 +3670,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- business_scope.
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- business_scope
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -3681,6 +3693,19 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: business_scope
|
||||
data_type: string
|
||||
description: |
|
||||
Business scope identifying the metric source.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "Old Dash"
|
||||
- "New Dash"
|
||||
- "API"
|
||||
- "UNSET"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
@ -4009,13 +4034,15 @@ models:
|
|||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_deal.
|
||||
- id_deal,
|
||||
- business_scope.
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
- business_scope
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
|
|
@ -4030,6 +4057,19 @@ models:
|
|||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: business_scope
|
||||
data_type: string
|
||||
description: |
|
||||
Business scope identifying the metric source.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "Old Dash"
|
||||
- "New Dash"
|
||||
- "API"
|
||||
- "UNSET"
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue