Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add YTD total to fct_monthly_active_students #242

Merged
merged 8 commits into from
Nov 27, 2024
3 changes: 3 additions & 0 deletions dbt/models/marts/metrics/_metrics__models.yml
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,9 @@ models:
description: the number of active students on given month, in given country
data_tests:
- not_null

- name: num_active_students_ytd
description: the number of unique students as a rolling total for each school year

data_tests:
- dbt_utils.unique_combination_of_columns:
Expand Down
91 changes: 74 additions & 17 deletions dbt/models/marts/metrics/fct_monthly_active_students.sql
Original file line number Diff line number Diff line change
@@ -1,25 +1,82 @@
{#
model: fct_active_students_monthly
changelog:
author version date comments
js 2.0 2024-09-17 init
"" 2.1 "" removing anonymous users from scope
#}

with active_students as (
select *
-- Step 0: Stage data
with
active_students as (
select
*,
date_trunc('month', activity_date) as activity_month
from {{ ref('dim_active_students') }}
),

first_active_month as (
select
student_id,
school_year,
min(activity_month) as first_activity_month
from active_students
group by student_id, school_year
),

combined as (
select
acs.school_year,
acs.activity_month,
acs.us_intl,
acs.country,
acs.student_id
from active_students as acs
left join first_active_month as fam
on acs.student_id = fam.student_id
and acs.school_year = fam.school_year
and acs.activity_month >= fam.first_activity_month
),

final as (
select
date_trunc('month',activity_date) as activity_month,
com.school_year,
com.activity_month,
com.us_intl,
com.country,
count(distinct com.student_id) as num_active_students,
count(distinct case
when com.activity_month = fam.first_activity_month
then com.student_id end) as num_new_students
from combined as com
left join first_active_month as fam
on com.student_id = fam.student_id
and com.school_year = fam.school_year
group by com.school_year, com.activity_month, com.us_intl, com.country
),

rolling_final_prep as (
select
school_year,
activity_month,
us_intl,
country,
count(distinct student_id) as num_active_students
from active_students
{{ dbt_utils.group_by(3) }} )

num_active_students,
num_new_students
from final
),

rolling_final as (
select
school_year,
activity_month,
us_intl,
country,
num_active_students,
sum(num_new_students) over (
partition by
school_year,
us_intl,
country
order by activity_month
rows between unbounded preceding and current row
) as num_active_students_ytd
from rolling_final_prep )

select *
from final
order by activity_month desc
from rolling_final
order by
school_year,
activity_month desc