Merged PR 3411: Guest journey metrics attributed to check-in date
# Description Here are all models for guest journey metrics attributed to check-in date with their monthly and MTD aggregation. I did a little modification on the assert_dimension_completeness test so it can have a list of metrics to check instead of having to put it separately for each one, let me know what you think @<Oriol Roqué Paniagua> and I can update it for all other models that are using that test and update as well al names from aggregated to agg (Or should I just do it in a separate PR??) I also checked the total values vs your models and the results make sense, there is some difference which is to be expected but nothing crazy. # 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: #23387
This commit is contained in:
commit
aeaf78df16
7 changed files with 648 additions and 6 deletions
|
|
@ -80,6 +80,12 @@ Please note that strings should be encoded with " ' your_value_here ' ",
|
|||
{% macro dim_dash() %}
|
||||
{{ return({"dimension": "'by_dash_source'", "dimension_value": "dash_source"}) }}
|
||||
{% endmacro %}
|
||||
{% macro dim_has_payment() %}
|
||||
{{ return({"dimension": "'by_has_payment'", "dimension_value": "has_payment"}) }}
|
||||
{% endmacro %}
|
||||
{% macro dim_has_id_check() %}
|
||||
{{ return({"dimension": "'by_has_id_check'", "dimension_value": "has_id_check"}) }}
|
||||
{% endmacro %}
|
||||
|
||||
/*
|
||||
Macro: get_kpi_dimensions_per_model
|
||||
|
|
@ -107,6 +113,11 @@ Provides a general assignemnt for the Dimensions available for each KPI
|
|||
{% set additional_dimensions = [dim_dash()] %}
|
||||
{% endif %}
|
||||
|
||||
{# Add entity-specific dimensions #}
|
||||
{% if entity_name == "CHECK_IN_ATTRIBUTED_GUEST_JOURNEYS" %}
|
||||
{% set additional_dimensions = [dim_has_payment(), dim_has_id_check()] %}
|
||||
{% endif %}
|
||||
|
||||
{# Combine base dimensions with additional dimensions for the specific model #}
|
||||
{% set dimensions = base_dimensions + additional_dimensions %}
|
||||
{{ return(dimensions) }}
|
||||
|
|
|
|||
|
|
@ -0,0 +1,35 @@
|
|||
{% set dimensions = get_kpi_dimensions_per_model("CHECK_IN_ATTRIBUTED_GUEST_JOURNEYS") %}
|
||||
|
||||
{{
|
||||
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(
|
||||
created_guest_journeys_not_cancelled
|
||||
) as created_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
started_guest_journeys_not_cancelled
|
||||
) as started_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
completed_guest_journeys_not_cancelled
|
||||
) as completed_guest_journeys_not_cancelled,
|
||||
sum(created_guest_journeys) as created_guest_journeys,
|
||||
sum(started_guest_journeys) as started_guest_journeys,
|
||||
sum(completed_guest_journeys) as completed_guest_journeys
|
||||
from {{ ref("int_kpis__metric_monthly_check_in_attributed_guest_journeys") }}
|
||||
group by 1, 2, 3, 4
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
|
|
@ -0,0 +1,35 @@
|
|||
{% set dimensions = get_kpi_dimensions_per_model("CHECK_IN_ATTRIBUTED_GUEST_JOURNEYS") %}
|
||||
|
||||
{{
|
||||
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(
|
||||
created_guest_journeys_not_cancelled
|
||||
) as created_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
started_guest_journeys_not_cancelled
|
||||
) as started_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
completed_guest_journeys_not_cancelled
|
||||
) as completed_guest_journeys_not_cancelled,
|
||||
sum(created_guest_journeys) as created_guest_journeys,
|
||||
sum(started_guest_journeys) as started_guest_journeys,
|
||||
sum(completed_guest_journeys) as completed_guest_journeys
|
||||
from {{ ref("int_kpis__metric_mtd_check_in_attributed_guest_journeys") }}
|
||||
group by 1, 2, 3, 4
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
|
|
@ -11,9 +11,9 @@ select
|
|||
b.check_in_date_utc as date,
|
||||
coalesce(icuh.id_deal, 'UNSET') as id_deal,
|
||||
case
|
||||
when vp.id_verification_to_payment is null then false else true
|
||||
when vp.id_verification_to_payment is null then 'W/O Payment' else 'With Payment'
|
||||
end as has_payment,
|
||||
case when v.id_verification is null then false else true end as has_id_check,
|
||||
case when v.id_verification is null then 'W/O Id Check' else 'With Id Check' end as has_id_check,
|
||||
-- Dimensions --
|
||||
coalesce(
|
||||
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
||||
|
|
|
|||
|
|
@ -0,0 +1,32 @@
|
|||
{{
|
||||
config(
|
||||
materialized="view",
|
||||
unique_key=["end_date", "id_deal", "has_payment", "has_id_check", "active_accommodations_per_deal_segmentation"],
|
||||
)
|
||||
}}
|
||||
|
||||
select
|
||||
-- Unique Key --
|
||||
d.first_day_month as start_date,
|
||||
d.date as end_date,
|
||||
b.id_deal,
|
||||
b.has_payment,
|
||||
b.has_id_check,
|
||||
-- Dimensions --
|
||||
b.active_accommodations_per_deal_segmentation,
|
||||
b.main_billing_country_iso_3_per_deal,
|
||||
-- Metrics --
|
||||
sum(b.created_guest_journeys_not_cancelled) as created_guest_journeys_not_cancelled,
|
||||
sum(b.started_guest_journeys_not_cancelled) as started_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
b.completed_guest_journeys_not_cancelled
|
||||
) as completed_guest_journeys_not_cancelled,
|
||||
sum(b.created_guest_journeys) as created_guest_journeys,
|
||||
sum(b.started_guest_journeys) as started_guest_journeys,
|
||||
sum(b.completed_guest_journeys) as completed_guest_journeys
|
||||
from {{ ref("int_kpis__dimension_dates") }} d
|
||||
left join
|
||||
{{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} b
|
||||
on date_trunc('month', b.date)::date = d.first_day_month
|
||||
where d.is_end_of_month = true and b.id_deal is not null
|
||||
group by 1, 2, 3, 4, 5, 6, 7
|
||||
|
|
@ -0,0 +1,33 @@
|
|||
{{
|
||||
config(
|
||||
materialized="view",
|
||||
unique_key=["end_date", "id_deal", "has_payment", "has_id_check", "active_accommodations_per_deal_segmentation"],
|
||||
)
|
||||
}}
|
||||
|
||||
select
|
||||
-- Unique Key --
|
||||
d.first_day_month as start_date,
|
||||
d.date as end_date,
|
||||
b.id_deal,
|
||||
b.has_payment,
|
||||
b.has_id_check,
|
||||
-- Dimensions --
|
||||
b.active_accommodations_per_deal_segmentation,
|
||||
b.main_billing_country_iso_3_per_deal,
|
||||
-- Metrics --
|
||||
sum(b.created_guest_journeys_not_cancelled) as created_guest_journeys_not_cancelled,
|
||||
sum(b.started_guest_journeys_not_cancelled) as started_guest_journeys_not_cancelled,
|
||||
sum(
|
||||
b.completed_guest_journeys_not_cancelled
|
||||
) as completed_guest_journeys_not_cancelled,
|
||||
sum(b.created_guest_journeys) as created_guest_journeys,
|
||||
sum(b.started_guest_journeys) as started_guest_journeys,
|
||||
sum(b.completed_guest_journeys) as completed_guest_journeys
|
||||
from {{ ref("int_kpis__dimension_dates") }} d
|
||||
left join
|
||||
{{ ref("int_kpis__metric_daily_check_in_attributed_guest_journeys") }} b
|
||||
on date_trunc('month', b.date)::date = d.first_day_month
|
||||
and extract(day from b.date) <= d.day
|
||||
where d.is_month_to_date = true and b.id_deal is not null
|
||||
group by 1, 2, 3, 4, 5, 6, 7
|
||||
|
|
@ -3111,13 +3111,25 @@ models:
|
|||
- not_null
|
||||
|
||||
- name: has_payment
|
||||
data_type: boolean
|
||||
description: True if there has been any guest payments on the guest journey.
|
||||
data_type: string
|
||||
description: Has there been any guest payments on the guest journey.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Payment
|
||||
- With Payment
|
||||
|
||||
- name: has_id_check
|
||||
data_type: boolean
|
||||
description: True if there verification in the guest journey
|
||||
data_type: string
|
||||
description: Does the verification in the guest journey
|
||||
includes Government Id Check for the bookings.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Id Check
|
||||
- With Id Check
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
|
|
@ -3177,3 +3189,487 @@ models:
|
|||
description: |
|
||||
Count of daily guest journeys completed in a given date and
|
||||
per specified dimension.
|
||||
|
||||
- name: int_kpis__metric_monthly_check_in_attributed_guest_journeys
|
||||
description: |
|
||||
This model computes the Monthly metrics associated with Guest Journeys
|
||||
attributed to Check-In date at the deepest granularity.
|
||||
|
||||
The unique key corresponds to:
|
||||
- end_date,
|
||||
- id_deal,
|
||||
- has_payment,
|
||||
- has_id_check,
|
||||
- active_accommodations_per_deal_segmentation.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- end_date
|
||||
- id_deal
|
||||
- has_payment
|
||||
- has_id_check
|
||||
- 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: character varying
|
||||
description: Unique identifier of an account.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: has_payment
|
||||
data_type: string
|
||||
description: Has there been any guest payments on the guest journey.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Payment
|
||||
- With Payment
|
||||
|
||||
- name: has_id_check
|
||||
data_type: string
|
||||
description: Does the verification in the guest journey
|
||||
includes Government Id Check for the bookings.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Id Check
|
||||
- With Id Check
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: text
|
||||
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: character varying
|
||||
description: |
|
||||
Main billing country of the host aggregated at Deal level.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys created, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys started, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys completed, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys created in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys started in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys completed in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_kpis__agg_monthly_check_in_attributed_guest_journeys
|
||||
description: |
|
||||
This model computes the dimension aggregation for Monthly metrics associated
|
||||
to Guest Journeys attributed to Check-In date.
|
||||
|
||||
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: text
|
||||
description: |
|
||||
The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: created_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: started_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: completed_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: created_guest_journeys
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: started_guest_journeys
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: completed_guest_journeys
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_deal
|
||||
- by_has_payment
|
||||
- by_has_id_check
|
||||
- by_billing_country
|
||||
- by_number_of_listings
|
||||
|
||||
- name: dimension_value
|
||||
data_type: text
|
||||
description: |
|
||||
The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys created, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys started, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys completed, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys created for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys started for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys completed for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_kpis__metric_mtd_check_in_attributed_guest_journeys
|
||||
description: |
|
||||
This model computes the Month-To-Date metrics associated with Guest Journeys
|
||||
attributed to Check-In date at the deepest granularity.
|
||||
|
||||
The unique key corresponds to:
|
||||
- end_date,
|
||||
- id_deal,
|
||||
- has_payment,
|
||||
- has_id_check,
|
||||
- active_accommodations_per_deal_segmentation.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- end_date
|
||||
- id_deal
|
||||
- has_payment
|
||||
- has_id_check
|
||||
- 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: character varying
|
||||
description: Unique identifier of an account.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: has_payment
|
||||
data_type: string
|
||||
description: Has there been any guest payments on the guest journey.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Payment
|
||||
- With Payment
|
||||
|
||||
- name: has_id_check
|
||||
data_type: string
|
||||
description: Does the verification in the guest journey
|
||||
includes Government Id Check for the bookings.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- W/O Id Check
|
||||
- With Id Check
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: text
|
||||
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: character varying
|
||||
description: |
|
||||
Main billing country of the host aggregated at Deal level.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys created, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys started, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys completed, excluding cancelled bookings,
|
||||
in a given date and per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys created in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys started in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Count of daily guest journeys completed in a given date and
|
||||
per specified dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_kpis__agg_mtd_check_in_attributed_guest_journeys
|
||||
description: |
|
||||
This model computes the dimension aggregation for Month-To-Date metrics associated
|
||||
to Guest Journeys attributed to Check-In date.
|
||||
|
||||
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: text
|
||||
description: |
|
||||
The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: created_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: started_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: completed_guest_journeys_not_cancelled
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: created_guest_journeys
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: started_guest_journeys
|
||||
- assert_dimension_completeness:
|
||||
metric_column_name: completed_guest_journeys
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_deal
|
||||
- by_has_payment
|
||||
- by_has_id_check
|
||||
- by_billing_country
|
||||
- by_number_of_listings
|
||||
|
||||
- name: dimension_value
|
||||
data_type: text
|
||||
description: |
|
||||
The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys created, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys started, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys_not_cancelled
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys completed, excluding
|
||||
cancelled bookings, for a given date, dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: created_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys created for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: started_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys started for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: completed_guest_journeys
|
||||
data_type: numeric
|
||||
description: |
|
||||
Monthly aggregated count of guest journeys completed for a given date,
|
||||
dimension, and value.
|
||||
tests:
|
||||
- not_null
|
||||
Loading…
Add table
Add a link
Reference in a new issue