Merged PR 3006: Integrating to staging Product Service related tables
# Description This PR integrates into staging the following Core tables, regarding New Pricing: - ProductService - ProductServiceToPrice - AppliedProductService (IT HAS BEEN REMOVED) Models are also documented in staging. Tables contain data already but not necessarily records for New Dash, since still we have not had any paid service applied into a booking / V2 has not been launched yet. New Dash modelisation for V2 will follow once these tables exist in staging, in order to be able to report 1) revenue and 2) services selected. # 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. - [ ] I've picked the right materialization for the affected models. **N/A, few records so not a big deal. Might need to change in the future.** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #20809
This commit is contained in:
parent
7d9d9faf71
commit
f2e21496fe
4 changed files with 285 additions and 0 deletions
|
|
@ -235,3 +235,13 @@ sources:
|
|||
identifier: ElectronicDepositUser
|
||||
- name: PayAway
|
||||
identifier: PayAway
|
||||
- name: ProductService
|
||||
identifier: ProductService
|
||||
- name: ProductServiceToPrice
|
||||
identifier: ProductServiceToPrice
|
||||
- name: BillingMethod
|
||||
identifier: BillingMethod
|
||||
- name: InvoicingMethod
|
||||
identifier: InvoicingMethod
|
||||
- name: PaymentType
|
||||
identifier: PaymentType
|
||||
|
|
|
|||
|
|
@ -520,3 +520,188 @@ models:
|
|||
Timestamp of when this data was extracted into DWH.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: stg_core__product_service
|
||||
description: |
|
||||
Contains all the product services operated by Truvi (Superhog) in the scope of
|
||||
New Pricing.
|
||||
|
||||
columns:
|
||||
- name: id_product_service
|
||||
data_type: integer
|
||||
description: |
|
||||
Identifier of the product service. Acts as the primary key for this table.
|
||||
tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: product_service_name
|
||||
data_type: string
|
||||
description: |
|
||||
CamelCase name of the product service. Uniquely identifies the product service.
|
||||
tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: product_service_full_name
|
||||
data_type: string
|
||||
description: |
|
||||
A more readable way to display the product service. It's mainly product_service_name
|
||||
with spaces in between words.
|
||||
tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: product_service_description
|
||||
data_type: string
|
||||
description: |
|
||||
A general description of the product service. It contains relevant information to understand
|
||||
how the new pricing services relate to old pricing services and/or previous nomenclature used.
|
||||
In some cases such as for waivers, it indicates who takes the risk.
|
||||
- name: product_service_binary_tier
|
||||
data_type: integer
|
||||
description: |
|
||||
Product service binary identifier (as powers of 2). It's a geometric progression with a common ratio
|
||||
of 2. It can be used to uniquely identify which product services apply within a product bundle (a
|
||||
combination of product services within a single bundle).
|
||||
The fact that it's a power of 2 is because it identifies if a product service is applied (true) or
|
||||
not applied (false). Thus, if in stg_core__user_product_bundle we have the value 257 in the
|
||||
chosen_product_services field, this indicates that the services contained are those whose flag is
|
||||
256 and 1, since 257 can only be attributed to 256+1 in powers of 2.
|
||||
Ideally, we should modelise the relation "this product bundle has these product services" with a
|
||||
dedicated model in DWH that duplicates the id_product_bundle as many times as id_product_service
|
||||
are applied, to ease up analytical needs.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this data was extracted into DWH.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: stg_core__product_service_to_price
|
||||
description: |
|
||||
Contains the relationship "this product service has this price in this currency"
|
||||
in the scope of New Pricing.
|
||||
Each product service per currency can have different:
|
||||
- Payment types (amount, percentage)
|
||||
- Price computation methods (per booking, per night)
|
||||
- Charging methods (post checkout, pre booking, at waiver payment, etc.)
|
||||
Additionally, it's possible that a price is modified at user level. This is identifiable
|
||||
by the id_user_product_bundle being set (custom price) vs. not set (default price).
|
||||
Each product service and currency line can be active in a given time frame, and this table
|
||||
also contains the history of previous, currently inactive, product services prices.
|
||||
|
||||
tests:
|
||||
- dbt_expectations.expect_column_pair_values_A_to_be_greater_than_B:
|
||||
column_A: ends_at_utc
|
||||
column_B: starts_at_utc
|
||||
or_equal: True
|
||||
|
||||
columns:
|
||||
- name: id_product_service_to_price
|
||||
data_type: integer
|
||||
description: |
|
||||
Identifier of the product service to price. Acts as the primary key for this table.
|
||||
tests:
|
||||
- unique
|
||||
- not_null
|
||||
- name: id_product_service
|
||||
data_type: integer
|
||||
description: |
|
||||
Identifier of the product service.
|
||||
tests:
|
||||
- not_null
|
||||
- name: id_currency
|
||||
data_type: integer
|
||||
description: |
|
||||
Identifier of the currency.
|
||||
tests:
|
||||
- not_null
|
||||
- name: payment_type
|
||||
data_type: string
|
||||
description: |
|
||||
Type of the payment.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "AMOUNT"
|
||||
- "PERCENTAGE"
|
||||
- name: price_base_unit
|
||||
data_type: string
|
||||
description: |
|
||||
Represents how the price value should be taken into account, either
|
||||
if the price is representing the total amount at booking level or
|
||||
it's a nightly fee.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "PER BOOKING"
|
||||
- "PER NIGHT"
|
||||
- name: invoicing_trigger
|
||||
data_type: string
|
||||
description: |
|
||||
Represents at which moment in time this service should be invoiced.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "PRE-BOOKING"
|
||||
- "POST-CHECKOUT"
|
||||
- "AT WAIVER PAYMENT"
|
||||
- "AT DEPOSIT PAYMENT"
|
||||
- "N/A"
|
||||
- name: id_user_product_bundle
|
||||
data_type: integer
|
||||
description: |
|
||||
Identifier of the user product bundle in which this product service to price
|
||||
is applied. It can be null, thus referring to a product bundle per user that
|
||||
uses a default price.
|
||||
- name: amount_local_curr
|
||||
data_type: decimal
|
||||
description: |
|
||||
Price amount of a given product service in the currency stated in id_currency.
|
||||
tests:
|
||||
- not_null
|
||||
- name: product_service_price_name
|
||||
data_type: string
|
||||
description: |
|
||||
The name given to a product service to price.
|
||||
- name: starts_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this product service to price starts to be active.
|
||||
tests:
|
||||
- not_null
|
||||
- name: ends_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this product service to price ends to be active.
|
||||
It can be null, thus meaning it's currently active.
|
||||
- name: has_no_end_date
|
||||
data_type: boolean
|
||||
description: |
|
||||
True when ends_at_utc is not set, false otherwise.
|
||||
- name: created_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this product service to price was created.
|
||||
- name: created_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date of when this product service to price was created.
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this product service to price was last updated.
|
||||
- name: updated_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date of when this product service to price was last updated.
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Timestamp of when this data was extracted into DWH.
|
||||
tests:
|
||||
- not_null
|
||||
|
|
|
|||
17
models/staging/core/stg_core__product_service.sql
Normal file
17
models/staging/core/stg_core__product_service.sql
Normal file
|
|
@ -0,0 +1,17 @@
|
|||
with
|
||||
raw_product_service as (select * from {{ source("core", "ProductService") }}),
|
||||
stg_core__product_service as (
|
||||
select
|
||||
{{ adapter.quote("Id") }} as id_product_service,
|
||||
|
||||
{{ adapter.quote("Name") }} as product_service_name,
|
||||
{{ adapter.quote("FullName") }} as product_service_full_name,
|
||||
{{ adapter.quote("Description") }} as product_service_description,
|
||||
{{ adapter.quote("ProductServiceFlag") }} as product_service_binary_tier,
|
||||
|
||||
{{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc
|
||||
|
||||
from raw_product_service
|
||||
)
|
||||
select *
|
||||
from stg_core__product_service
|
||||
73
models/staging/core/stg_core__product_service_to_price.sql
Normal file
73
models/staging/core/stg_core__product_service_to_price.sql
Normal file
|
|
@ -0,0 +1,73 @@
|
|||
with
|
||||
raw_product_service_to_price as (
|
||||
select * from {{ source("core", "ProductServiceToPrice") }}
|
||||
),
|
||||
raw_invoicing_trigger as (
|
||||
select
|
||||
{{ adapter.quote("Id") }} as id,
|
||||
upper({{ adapter.quote("FullName") }}) as invoicing_trigger
|
||||
from {{ source("core", "InvoicingMethod") }}
|
||||
),
|
||||
raw_price_base_unit as (
|
||||
select
|
||||
{{ adapter.quote("Id") }} as id,
|
||||
upper({{ adapter.quote("FullName") }}) as price_base_unit
|
||||
from {{ source("core", "BillingMethod") }}
|
||||
),
|
||||
raw_payment_type as (
|
||||
select
|
||||
{{ adapter.quote("Id") }} as id,
|
||||
upper({{ adapter.quote("FullName") }}) as payment_type
|
||||
from {{ source("core", "PaymentType") }}
|
||||
),
|
||||
stg_core__product_service_to_price as (
|
||||
select
|
||||
{{ adapter.quote("Id") }} as id_product_service_to_price,
|
||||
{{ adapter.quote("ProductServiceId") }} as id_product_service,
|
||||
{{ adapter.quote("CurrencyId") }} as id_currency,
|
||||
{{ adapter.quote("PaymentTypeId") }} as id_payment_type,
|
||||
{{ adapter.quote("BillingMethodId") }} as id_price_base_unit,
|
||||
{{ adapter.quote("InvoicingMethodId") }} as id_invoicing_trigger,
|
||||
|
||||
{{ adapter.quote("UserProductBundleId") }} as id_user_product_bundle,
|
||||
|
||||
{{ adapter.quote("Amount") }} as amount_local_curr,
|
||||
{{ adapter.quote("DisplayName") }} as product_service_price_name,
|
||||
|
||||
{{ adapter.quote("StartDate") }} as starts_at_utc,
|
||||
{{ adapter.quote("EndDate") }} as ends_at_utc,
|
||||
case
|
||||
when {{ adapter.quote("EndDate") }} is null then true else false
|
||||
end as has_no_end_date,
|
||||
|
||||
{{ adapter.quote("CreatedDate") }} as created_at_utc,
|
||||
cast({{ adapter.quote("CreatedDate") }} as date) as created_date_utc,
|
||||
{{ adapter.quote("UpdatedDate") }} as updated_at_utc,
|
||||
cast({{ adapter.quote("UpdatedDate") }} as date) as updated_date_utc,
|
||||
|
||||
{{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc
|
||||
|
||||
from raw_product_service_to_price
|
||||
)
|
||||
select
|
||||
pstp.id_product_service_to_price,
|
||||
pstp.id_product_service,
|
||||
pstp.id_currency,
|
||||
pt.payment_type,
|
||||
pcm.price_base_unit,
|
||||
cm.invoicing_trigger,
|
||||
pstp.id_user_product_bundle,
|
||||
pstp.amount_local_curr,
|
||||
pstp.product_service_price_name,
|
||||
pstp.starts_at_utc,
|
||||
pstp.ends_at_utc,
|
||||
pstp.has_no_end_date,
|
||||
pstp.created_at_utc,
|
||||
pstp.created_date_utc,
|
||||
pstp.updated_at_utc,
|
||||
pstp.updated_date_utc,
|
||||
pstp.dwh_extracted_at_utc
|
||||
from stg_core__product_service_to_price pstp
|
||||
left join raw_payment_type pt on pstp.id_payment_type = pt.id
|
||||
left join raw_price_base_unit pcm on pstp.id_price_base_unit = pcm.id
|
||||
left join raw_invoicing_trigger cm on pstp.id_invoicing_trigger = cm.id
|
||||
Loading…
Add table
Add a link
Reference in a new issue