Merged PR 2883: Payaway per month and user
# Description This PR adds an intermediate tables that holds a combo of all payaway plans with the months (technically, combinations of first day and last day of month) when the plan was the relevant one for invoicing purposes. The goal is to have this as an intermediate helper for some tax related logic in verification payments. # 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: #20043
This commit is contained in:
commit
4bafeba787
2 changed files with 126 additions and 0 deletions
|
|
@ -0,0 +1,51 @@
|
|||
with
|
||||
int_core__payaway as (select * from {{ ref("int_core__payaway") }}),
|
||||
int_dates as (select * from {{ ref("int_dates") }}),
|
||||
active_payaway_per_month as (
|
||||
select distinct
|
||||
pa.id_payaway_plan,
|
||||
pa.id_user_host,
|
||||
pa.start_at_utc,
|
||||
pa.end_at_utc,
|
||||
pa.created_at_utc,
|
||||
d.month_start_date as active_in_month_start_date_utc,
|
||||
d.month_end_date as active_in_month_end_date_utc
|
||||
from int_core__payaway pa
|
||||
inner join
|
||||
int_dates d
|
||||
on d.date_day
|
||||
between pa.start_at_utc and coalesce(pa.end_at_utc, '2099-12-31T23:59:59Z')
|
||||
-- open ended plans have null values, so we apply this to make the
|
||||
-- between work
|
||||
where
|
||||
d.date_day < (date_trunc('month', current_date) + interval '1 month')::date
|
||||
-- no sense in matching stuff in the future. The above statement returns
|
||||
-- the first day of next month
|
||||
),
|
||||
sorted_payaway_plans as (
|
||||
select
|
||||
id_payaway_plan,
|
||||
id_user_host,
|
||||
start_at_utc,
|
||||
end_at_utc,
|
||||
created_at_utc,
|
||||
active_in_month_start_date_utc,
|
||||
active_in_month_end_date_utc,
|
||||
row_number() over (
|
||||
partition by id_user_host, active_in_month_end_date_utc
|
||||
order by created_at_utc desc
|
||||
-- the latest active, created plan is the one that will be
|
||||
-- valid for the month
|
||||
) as rn
|
||||
from active_payaway_per_month
|
||||
)
|
||||
select
|
||||
id_payaway_plan,
|
||||
id_user_host,
|
||||
start_at_utc,
|
||||
end_at_utc,
|
||||
created_at_utc,
|
||||
active_in_month_start_date_utc,
|
||||
active_in_month_end_date_utc
|
||||
from sorted_payaway_plans
|
||||
where rn = 1
|
||||
|
|
@ -3184,6 +3184,81 @@ models:
|
|||
plans happened during that month.
|
||||
tests:
|
||||
- not_null
|
||||
- name: int_core__payaway_per_month_user
|
||||
description: |
|
||||
This model contains the payaway plans that were considered as active
|
||||
for the invoicing process each month. This is, given that more than
|
||||
one plan coexist within the same month, we take the one plan that
|
||||
was active at the end of the month. This is the one that should apply for
|
||||
the invoicing of that month, indisctintly of the fact that there was other
|
||||
plans active before.
|
||||
|
||||
The time scope of the model is limited to the current month. This means
|
||||
that, even though some plans will end in future dates or have no planned
|
||||
end date, this table will only reflect activeness within months up to the
|
||||
current month.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- id_user_host
|
||||
- id_payaway_plan
|
||||
- active_in_month_start_date_utc
|
||||
|
||||
columns:
|
||||
- name: id_payaway_plan
|
||||
data_type: bigint
|
||||
description: |
|
||||
The unique identifier of this table, representing
|
||||
the identifier of the payaway plan.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: id_user_host
|
||||
data_type: string
|
||||
description: |
|
||||
The unique identifier of the user host that has
|
||||
a price plan.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: start_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Original timestamp of when a given plan started to be active.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: end_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Original timestamp of when a given plan stopped being active. If it's
|
||||
null, it means the plan is open ended (has no planned end date yet).
|
||||
|
||||
- name: created_at_utc
|
||||
data_type: timestamp
|
||||
description: |
|
||||
Original timestamp of when a given plan was created.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: active_in_month_start_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date that refers to the first day of the month on which we will
|
||||
consider a plan as active. If we're interested in retrieving the
|
||||
information from June, this date will be the 1st of June.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: active_in_month_end_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date that refers to the last day of the month on which we will
|
||||
consider a plan as active. If we're interested in retrieving the
|
||||
information from June, this date will be the 30th of June.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: int_core__deal
|
||||
description: |
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue