Merged PR 3419: Adds Host Resolutions metrics in new KPIs
# Description Adds 2 new metrics: - xero_host_resolution_amount_paid_in_gbp - xero_host_resolution_payment_count Effectively it will split the "real" invoicing sources of revenue from "host resolution payments". This was already reading from 2 different Xero models (bank transactions vs. sales). We have as usual: - 1 Daily metric model - 2 MTD/Monthly metric model - 2 MTD/Monthly agg model (I already changed the name to agg instead of aggregated) - 1 test to compare the values match the current setup # 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. - [NA] 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: #23565
This commit is contained in:
parent
9b0c7161e3
commit
b31a6ba194
7 changed files with 571 additions and 9 deletions
|
|
@ -0,0 +1,27 @@
|
||||||
|
{% set dimensions = get_kpi_dimensions_per_model("HOST_RESOLUTIONS") %}
|
||||||
|
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="table", unique_key=["end_date", "dimension", "dimension_value"]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
|
||||||
|
{% for dimension in dimensions %}
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
start_date,
|
||||||
|
end_date,
|
||||||
|
{{ dimension.dimension }} as dimension,
|
||||||
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
|
-- Metrics --
|
||||||
|
sum(
|
||||||
|
xero_host_resolution_amount_paid_in_gbp
|
||||||
|
) as xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
sum(xero_host_resolution_payment_count) as xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__metric_monthly_host_resolutions") }}
|
||||||
|
group by 1, 2, 3, 4
|
||||||
|
{% if not loop.last %}
|
||||||
|
union all
|
||||||
|
{% endif %}
|
||||||
|
{% endfor %}
|
||||||
|
|
@ -0,0 +1,27 @@
|
||||||
|
{% set dimensions = get_kpi_dimensions_per_model("HOST_RESOLUTIONS") %}
|
||||||
|
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="table", unique_key=["end_date", "dimension", "dimension_value"]
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
|
||||||
|
{% for dimension in dimensions %}
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
start_date,
|
||||||
|
end_date,
|
||||||
|
{{ dimension.dimension }} as dimension,
|
||||||
|
{{ dimension.dimension_value }} as dimension_value,
|
||||||
|
-- Metrics --
|
||||||
|
sum(
|
||||||
|
xero_host_resolution_amount_paid_in_gbp
|
||||||
|
) as xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
sum(xero_host_resolution_payment_count) as xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__metric_mtd_host_resolutions") }}
|
||||||
|
group by 1, 2, 3, 4
|
||||||
|
{% if not loop.last %}
|
||||||
|
union all
|
||||||
|
{% endif %}
|
||||||
|
{% endfor %}
|
||||||
|
|
@ -0,0 +1,29 @@
|
||||||
|
{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %}
|
||||||
|
|
||||||
|
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
ixbt.transaction_date_utc as date,
|
||||||
|
coalesce(ixc.id_deal, 'UNSET') as id_deal,
|
||||||
|
-- Dimensions --
|
||||||
|
coalesce(
|
||||||
|
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||||
|
) as main_billing_country_iso_3_per_deal,
|
||||||
|
coalesce(
|
||||||
|
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
||||||
|
) as active_accommodations_per_deal_segmentation,
|
||||||
|
-- Metrics --
|
||||||
|
sum(ixbtli.line_amount_wo_taxes_in_gbp) as xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
count(distinct ixbt.id_bank_transaction) as xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_xero__bank_transactions") }} as ixbt
|
||||||
|
inner join
|
||||||
|
{{ ref("int_xero__bank_transaction_line_items") }} as ixbtli
|
||||||
|
on ixbt.id_bank_transaction = ixbtli.id_bank_transaction
|
||||||
|
and upper(ixbtli.account_name) in {{ resolutions_host_payment_account_name }}
|
||||||
|
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_daily_accommodation") }} as icmas
|
||||||
|
on ixc.id_deal = icmas.id_deal
|
||||||
|
and ixbt.transaction_date_utc = icmas.date
|
||||||
|
group by 1, 2, 3, 4
|
||||||
|
|
@ -0,0 +1,30 @@
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="view",
|
||||||
|
unique_key=[
|
||||||
|
"end_date",
|
||||||
|
"id_deal",
|
||||||
|
"active_accommodations_per_deal_segmentation",
|
||||||
|
],
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
d.first_day_month as start_date,
|
||||||
|
d.date as end_date,
|
||||||
|
hr.id_deal,
|
||||||
|
hr.active_accommodations_per_deal_segmentation,
|
||||||
|
-- Dimensions --
|
||||||
|
hr.main_billing_country_iso_3_per_deal,
|
||||||
|
-- Metrics --
|
||||||
|
sum(
|
||||||
|
hr.xero_host_resolution_amount_paid_in_gbp
|
||||||
|
) as xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
sum(hr.xero_host_resolution_payment_count) as xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__dimension_dates") }} d
|
||||||
|
left join
|
||||||
|
{{ ref("int_kpis__metric_daily_host_resolutions") }} hr
|
||||||
|
on date_trunc('month', hr.date)::date = d.first_day_month
|
||||||
|
where d.is_end_of_month = true and hr.id_deal is not null
|
||||||
|
group by 1, 2, 3, 4, 5
|
||||||
|
|
@ -0,0 +1,31 @@
|
||||||
|
{{
|
||||||
|
config(
|
||||||
|
materialized="view",
|
||||||
|
unique_key=[
|
||||||
|
"end_date",
|
||||||
|
"id_deal",
|
||||||
|
"active_accommodations_per_deal_segmentation",
|
||||||
|
],
|
||||||
|
)
|
||||||
|
}}
|
||||||
|
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
d.first_day_month as start_date,
|
||||||
|
d.date as end_date,
|
||||||
|
hr.id_deal,
|
||||||
|
hr.active_accommodations_per_deal_segmentation,
|
||||||
|
-- Dimensions --
|
||||||
|
hr.main_billing_country_iso_3_per_deal,
|
||||||
|
-- Metrics --
|
||||||
|
sum(
|
||||||
|
hr.xero_host_resolution_amount_paid_in_gbp
|
||||||
|
) as xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
sum(hr.xero_host_resolution_payment_count) as xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__dimension_dates") }} d
|
||||||
|
left join
|
||||||
|
{{ ref("int_kpis__metric_daily_host_resolutions") }} hr
|
||||||
|
on date_trunc('month', hr.date)::date = d.first_day_month
|
||||||
|
and extract(day from hr.date) <= d.day
|
||||||
|
where d.is_month_to_date = true and hr.id_deal is not null
|
||||||
|
group by 1, 2, 3, 4, 5
|
||||||
|
|
@ -3123,7 +3123,7 @@ models:
|
||||||
- name: has_id_check
|
- name: has_id_check
|
||||||
data_type: string
|
data_type: string
|
||||||
description: Does the verification in the guest journey
|
description: Does the verification in the guest journey
|
||||||
includes Government Id Check for the bookings.
|
includes Government Id Check for the bookings.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
|
|
@ -3189,7 +3189,7 @@ models:
|
||||||
description: |
|
description: |
|
||||||
Count of daily guest journeys completed in a given date and
|
Count of daily guest journeys completed in a given date and
|
||||||
per specified dimension.
|
per specified dimension.
|
||||||
|
|
||||||
- name: int_kpis__metric_monthly_check_in_attributed_guest_journeys
|
- name: int_kpis__metric_monthly_check_in_attributed_guest_journeys
|
||||||
description: |
|
description: |
|
||||||
This model computes the Monthly metrics associated with Guest Journeys
|
This model computes the Monthly metrics associated with Guest Journeys
|
||||||
|
|
@ -3245,7 +3245,7 @@ models:
|
||||||
- name: has_id_check
|
- name: has_id_check
|
||||||
data_type: string
|
data_type: string
|
||||||
description: Does the verification in the guest journey
|
description: Does the verification in the guest journey
|
||||||
includes Government Id Check for the bookings.
|
include Government Id Check for the bookings.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
|
|
@ -3261,7 +3261,7 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
values:
|
values:
|
||||||
- "0"
|
- "0"
|
||||||
- "01-05"
|
- "01-05"
|
||||||
- "06-20"
|
- "06-20"
|
||||||
|
|
@ -3369,7 +3369,7 @@ models:
|
||||||
- assert_dimension_completeness:
|
- assert_dimension_completeness:
|
||||||
metric_column_name: completed_guest_journeys
|
metric_column_name: completed_guest_journeys
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
values:
|
values:
|
||||||
- global
|
- global
|
||||||
- by_deal
|
- by_deal
|
||||||
- by_has_payment
|
- by_has_payment
|
||||||
|
|
@ -3487,7 +3487,7 @@ models:
|
||||||
- name: has_id_check
|
- name: has_id_check
|
||||||
data_type: string
|
data_type: string
|
||||||
description: Does the verification in the guest journey
|
description: Does the verification in the guest journey
|
||||||
includes Government Id Check for the bookings.
|
include Government Id Check for the bookings.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
|
|
@ -3503,7 +3503,7 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
values:
|
values:
|
||||||
- "0"
|
- "0"
|
||||||
- "01-05"
|
- "01-05"
|
||||||
- "06-20"
|
- "06-20"
|
||||||
|
|
@ -3611,7 +3611,7 @@ models:
|
||||||
- assert_dimension_completeness:
|
- assert_dimension_completeness:
|
||||||
metric_column_name: completed_guest_journeys
|
metric_column_name: completed_guest_journeys
|
||||||
- accepted_values:
|
- accepted_values:
|
||||||
values:
|
values:
|
||||||
- global
|
- global
|
||||||
- by_deal
|
- by_deal
|
||||||
- by_has_payment
|
- by_has_payment
|
||||||
|
|
@ -3672,4 +3672,342 @@ models:
|
||||||
Monthly aggregated count of guest journeys completed for a given date,
|
Monthly aggregated count of guest journeys completed for a given date,
|
||||||
dimension, and value.
|
dimension, and value.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: int_kpis__metric_daily_host_resolutions
|
||||||
|
description: |
|
||||||
|
This model computes the Daily Host Resolutions at the deepest granularity.
|
||||||
|
|
||||||
|
The unique key corresponds to the deepest granularity of the model,
|
||||||
|
in this case:
|
||||||
|
- date,
|
||||||
|
- id_deal.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- date
|
||||||
|
- id_deal
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: date
|
||||||
|
data_type: date
|
||||||
|
description: Date of when Host Resolutions transaction happened.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: string
|
||||||
|
description: Unique identifier of an account.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: active_accommodations_per_deal_segmentation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Segment value based on the number of listings booked in 12 months
|
||||||
|
for a given deal and date.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "0"
|
||||||
|
- "01-05"
|
||||||
|
- "06-20"
|
||||||
|
- "21-60"
|
||||||
|
- "61+"
|
||||||
|
- "UNSET"
|
||||||
|
|
||||||
|
- name: main_billing_country_iso_3_per_deal
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Main billing country of the host aggregated at Deal level.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: xero_host_resolution_payment_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of daily Host Resolution Payment Count in a given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of daily Host Resolution Amount Paid, in GBP, in a given
|
||||||
|
date and per specified dimension.
|
||||||
|
|
||||||
|
- name: int_kpis__metric_monthly_host_resolutions
|
||||||
|
description: |
|
||||||
|
This model computes the Monthly Host Resolutions at the
|
||||||
|
deepest granularity.
|
||||||
|
Be aware that any dimension that can change over the monthly period,
|
||||||
|
such as daily segmentations, are included in the primary key of the
|
||||||
|
model.
|
||||||
|
|
||||||
|
The unique key corresponds to:
|
||||||
|
- end_date,
|
||||||
|
- id_deal,
|
||||||
|
- active_accommodations_per_deal_segmentation.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- end_date
|
||||||
|
- id_deal
|
||||||
|
- active_accommodations_per_deal_segmentation
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: start_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The start date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: end_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The end date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: string
|
||||||
|
description: Unique identifier of an account.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: active_accommodations_per_deal_segmentation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Segment value based on the number of listings booked in 12 months
|
||||||
|
for a given deal and date.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "0"
|
||||||
|
- "01-05"
|
||||||
|
- "06-20"
|
||||||
|
- "21-60"
|
||||||
|
- "61+"
|
||||||
|
- "UNSET"
|
||||||
|
|
||||||
|
- name: main_billing_country_iso_3_per_deal
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Main billing country of the host aggregated at Deal level.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: xero_host_resolution_payment_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of accumulated Host Resolution Payment Count in a
|
||||||
|
given month and per specified dimension.
|
||||||
|
|
||||||
|
- name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of accumulated Host Resolution Amount Paid, in GBP, in a
|
||||||
|
given month and per specified dimension.
|
||||||
|
|
||||||
|
- name: int_kpis__metric_mtd_host_resolutions
|
||||||
|
description: |
|
||||||
|
This model computes the Month-To-Date Host Resolutions at the
|
||||||
|
deepest granularity.
|
||||||
|
Be aware that any dimension that can change over the monthly period,
|
||||||
|
such as daily segmentations, are included in the primary key of the
|
||||||
|
model.
|
||||||
|
|
||||||
|
The unique key corresponds to:
|
||||||
|
- end_date,
|
||||||
|
- id_deal,
|
||||||
|
- active_accommodations_per_deal_segmentation.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- end_date
|
||||||
|
- id_deal
|
||||||
|
- active_accommodations_per_deal_segmentation
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: start_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The start date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: end_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The end date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: id_deal
|
||||||
|
data_type: string
|
||||||
|
description: Unique identifier of an account.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: active_accommodations_per_deal_segmentation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Segment value based on the number of listings booked in 12 months
|
||||||
|
for a given deal and date.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "0"
|
||||||
|
- "01-05"
|
||||||
|
- "06-20"
|
||||||
|
- "21-60"
|
||||||
|
- "61+"
|
||||||
|
- "UNSET"
|
||||||
|
|
||||||
|
- name: main_billing_country_iso_3_per_deal
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Main billing country of the host aggregated at Deal level.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: xero_host_resolution_payment_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
Count of accumulated Host Resolution Payment Count in a
|
||||||
|
given month up to the given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
Sum of accumulated Host Resolution Amount Paid, in GBP, in a
|
||||||
|
given month up to the given date and per specified dimension.
|
||||||
|
|
||||||
|
- name: int_kpis__agg_monthly_host_resolutions
|
||||||
|
description: |
|
||||||
|
This model computes the dimension aggregation for
|
||||||
|
Monthly Host Resolutions.
|
||||||
|
|
||||||
|
The primary key of this model is end_date, dimension
|
||||||
|
and dimension_value.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- end_date
|
||||||
|
- dimension
|
||||||
|
- dimension_value
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: start_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The start date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: end_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The end date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: dimension
|
||||||
|
data_type: string
|
||||||
|
description: The dimension or granularity of the metrics.
|
||||||
|
tests:
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: xero_host_resolution_payment_count
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- global
|
||||||
|
- by_number_of_listings
|
||||||
|
- by_billing_country
|
||||||
|
- by_deal
|
||||||
|
|
||||||
|
- name: dimension_value
|
||||||
|
data_type: string
|
||||||
|
description: The value or segment available for the selected dimension.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: xero_host_resolution_payment_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The monthly Host Resolution Payment Count for a given date, dimension and value.
|
||||||
|
|
||||||
|
- name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
The monthly Host Resolution Amount Paid, in GBP, for a
|
||||||
|
given date, dimension and value.
|
||||||
|
|
||||||
|
- name: int_kpis__agg_mtd_host_resolutions
|
||||||
|
description: |
|
||||||
|
This model computes the dimension aggregation for
|
||||||
|
Month-To-Date Host Resolutions.
|
||||||
|
|
||||||
|
The primary key of this model is end_date, dimension
|
||||||
|
and dimension_value.
|
||||||
|
|
||||||
|
tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- end_date
|
||||||
|
- dimension
|
||||||
|
- dimension_value
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: start_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The start date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: end_date
|
||||||
|
data_type: date
|
||||||
|
description: |
|
||||||
|
The end date of the time range considered for the metrics in this record.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: dimension
|
||||||
|
data_type: string
|
||||||
|
description: The dimension or granularity of the metrics.
|
||||||
|
tests:
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: xero_host_resolution_payment_count
|
||||||
|
- assert_dimension_completeness:
|
||||||
|
metric_column_name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- global
|
||||||
|
- by_number_of_listings
|
||||||
|
- by_billing_country
|
||||||
|
- by_deal
|
||||||
|
|
||||||
|
- name: dimension_value
|
||||||
|
data_type: string
|
||||||
|
description: The value or segment available for the selected dimension.
|
||||||
|
tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: xero_host_resolution_payment_count
|
||||||
|
data_type: bigint
|
||||||
|
description: |
|
||||||
|
The month-to-date Host Resolution Payment Count for a given date, dimension and value.
|
||||||
|
|
||||||
|
- name: xero_host_resolution_amount_paid_in_gbp
|
||||||
|
data_type: decimal
|
||||||
|
description: |
|
||||||
|
The month-to-date Host Resolution Amount Paid, in GBP, for a
|
||||||
|
given date, dimension and value.
|
||||||
|
|
|
||||||
80
tests/tmp_kpis_refactor_equivalent_host_resolutions.sql
Normal file
80
tests/tmp_kpis_refactor_equivalent_host_resolutions.sql
Normal file
|
|
@ -0,0 +1,80 @@
|
||||||
|
{% set min_date = "2022-01-01" %}
|
||||||
|
{% set dimensions = ("global", "by_billing_country") %}
|
||||||
|
-- "by_number_of_listings" excluded on purpose - there's differences because of daily
|
||||||
|
-- segmentation
|
||||||
|
with
|
||||||
|
new_mtd_host_resolutions as (
|
||||||
|
select
|
||||||
|
end_date as date,
|
||||||
|
dimension,
|
||||||
|
dimension_value,
|
||||||
|
xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__agg_mtd_host_resolutions") }}
|
||||||
|
where
|
||||||
|
end_date >= '{{ min_date }}'
|
||||||
|
and dimension in {{ dimensions }}
|
||||||
|
and dimension_value <> 'UNSET'
|
||||||
|
),
|
||||||
|
new_monthly_host_resolutions as (
|
||||||
|
select
|
||||||
|
end_date as date,
|
||||||
|
dimension,
|
||||||
|
dimension_value,
|
||||||
|
xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_kpis__agg_monthly_host_resolutions") }}
|
||||||
|
where
|
||||||
|
end_date >= '{{ min_date }}'
|
||||||
|
and dimension in {{ dimensions }}
|
||||||
|
and dimension_value <> 'UNSET'
|
||||||
|
),
|
||||||
|
new_host_resolutions as (
|
||||||
|
select *
|
||||||
|
from new_mtd_host_resolutions
|
||||||
|
union all
|
||||||
|
select *
|
||||||
|
from new_monthly_host_resolutions
|
||||||
|
),
|
||||||
|
old_host_resolutions as (
|
||||||
|
select
|
||||||
|
date,
|
||||||
|
dimension,
|
||||||
|
dimension_value,
|
||||||
|
xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
xero_host_resolution_payment_count
|
||||||
|
from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||||
|
where date >= '{{ min_date }}' and dimension in {{ dimensions }}
|
||||||
|
),
|
||||||
|
comparison as (
|
||||||
|
select
|
||||||
|
coalesce(o.date, n.date) as date,
|
||||||
|
coalesce(o.dimension, n.dimension) as dimension,
|
||||||
|
coalesce(o.dimension_value, n.dimension_value) as dimension_value,
|
||||||
|
o.xero_host_resolution_amount_paid_in_gbp
|
||||||
|
as old_xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
n.xero_host_resolution_amount_paid_in_gbp
|
||||||
|
as new_xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
coalesce(o.xero_host_resolution_amount_paid_in_gbp, 0) - coalesce(
|
||||||
|
n.xero_host_resolution_amount_paid_in_gbp, 0
|
||||||
|
) as diff_xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
o.xero_host_resolution_payment_count
|
||||||
|
as old_xero_host_resolution_payment_count,
|
||||||
|
n.xero_host_resolution_payment_count
|
||||||
|
as new_xero_host_resolution_payment_count,
|
||||||
|
coalesce(o.xero_host_resolution_payment_count, 0) - coalesce(
|
||||||
|
n.xero_host_resolution_payment_count, 0
|
||||||
|
) as diff_xero_host_resolution_payment_count
|
||||||
|
from old_host_resolutions o
|
||||||
|
full outer join
|
||||||
|
new_host_resolutions n
|
||||||
|
on o.date = n.date
|
||||||
|
and o.dimension = n.dimension
|
||||||
|
and o.dimension_value = n.dimension_value
|
||||||
|
)
|
||||||
|
select *
|
||||||
|
from comparison
|
||||||
|
where
|
||||||
|
diff_xero_host_resolution_amount_paid_in_gbp <> 0
|
||||||
|
or diff_xero_host_resolution_payment_count <> 0
|
||||||
|
order by date desc
|
||||||
Loading…
Add table
Add a link
Reference in a new issue