From c08324a081b838f9586f97d454e0661451915e77 Mon Sep 17 00:00:00 2001 From: Jordan Springer Date: Mon, 25 Nov 2024 19:11:17 +0000 Subject: [PATCH 1/5] stashing --- .../metrics/fct_monthly_active_students.sql | 39 ++++++++++++++++--- 1 file changed, 33 insertions(+), 6 deletions(-) diff --git a/dbt/models/marts/metrics/fct_monthly_active_students.sql b/dbt/models/marts/metrics/fct_monthly_active_students.sql index a82c0b49..56991d55 100644 --- a/dbt/models/marts/metrics/fct_monthly_active_students.sql +++ b/dbt/models/marts/metrics/fct_monthly_active_students.sql @@ -11,15 +11,42 @@ with active_students as ( from {{ ref('dim_active_students') }} ), -final as ( +school_years as ( + select * + from {{ref('int_school_years') }} +), + +combined as ( select - date_trunc('month',activity_date) as activity_month, + sy.school_year, + date_trunc('month', activity_date) as activity_month, us_intl, country, count(distinct student_id) as num_active_students - from active_students - {{ dbt_utils.group_by(3) }} ) + from active_students + join school_years as sy + on active_students.activity_date + between sy.started_at + and sy.ended_at + {{ dbt_utils.group_by(4) }} +), + +final as ( + select + school_year, + activity_month, + us_intl, + country, + num_active_students, + sum(num_active_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 combined ) select * -from final -order by activity_month desc \ No newline at end of file +from final \ No newline at end of file From 1a21f128c33fe7347e7e6cb6c109660af0e7170b Mon Sep 17 00:00:00 2001 From: Jordan Springer Date: Tue, 26 Nov 2024 20:26:06 +0000 Subject: [PATCH 2/5] fixing final rolling count to capture only first activity students --- .../metrics/fct_monthly_active_students.sql | 64 +++++++++++++------ 1 file changed, 44 insertions(+), 20 deletions(-) diff --git a/dbt/models/marts/metrics/fct_monthly_active_students.sql b/dbt/models/marts/metrics/fct_monthly_active_students.sql index 56991d55..733f4038 100644 --- a/dbt/models/marts/metrics/fct_monthly_active_students.sql +++ b/dbt/models/marts/metrics/fct_monthly_active_students.sql @@ -1,13 +1,9 @@ -{# - 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') }} ), @@ -16,22 +12,48 @@ school_years as ( from {{ref('int_school_years') }} ), +first_active_month as ( + select + student_id, + min(activity_month) as first_activity_month + from active_students + group by student_id +), + combined as ( select sy.school_year, - date_trunc('month', activity_date) as activity_month, + activity_month, us_intl, country, - count(distinct student_id) as num_active_students + student_id from active_students join school_years as sy on active_students.activity_date between sy.started_at and sy.ended_at - {{ dbt_utils.group_by(4) }} ), final as ( + select + 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 fam.student_id end) as num_active_students_ytd + + from combined as com + left join first_active_month as fam + on com.student_id = fam.student_id + and com.activity_month = fam.first_activity_month + + {{ dbt_utils.group_by(4) }} +), + +rolling_final as ( select school_year, activity_month, @@ -42,11 +64,13 @@ final as ( partition by school_year, us_intl, - country - order by activity_month - rows between unbounded preceding and current row - ) as num_active_students_ytd - from combined ) - + country + order by activity_month + rows between unbounded preceding + and current row) as num_active_students_ytd + from final + {{ dbt_utils.group_by(5) }} ) + select * -from final \ No newline at end of file +from rolling_final +order by activity_month desc \ No newline at end of file From 49e02b9acf02fc044c21b2c6fa03b86f4252fb81 Mon Sep 17 00:00:00 2001 From: Cory Kind Date: Tue, 26 Nov 2024 22:00:14 +0000 Subject: [PATCH 3/5] - adding school_year to first_active_month and to the later join - editing the sum for ytd to be the active students ytd rather than active_students --- .../marts/metrics/fct_monthly_active_students.sql | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/dbt/models/marts/metrics/fct_monthly_active_students.sql b/dbt/models/marts/metrics/fct_monthly_active_students.sql index 733f4038..bbb12db1 100644 --- a/dbt/models/marts/metrics/fct_monthly_active_students.sql +++ b/dbt/models/marts/metrics/fct_monthly_active_students.sql @@ -14,10 +14,10 @@ school_years as ( first_active_month as ( select - student_id, + student_id, school_year, min(activity_month) as first_activity_month from active_students - group by student_id + group by student_id, school_year ), combined as ( @@ -48,7 +48,7 @@ final as ( from combined as com left join first_active_month as fam on com.student_id = fam.student_id - and com.activity_month = fam.first_activity_month + and com.school_year = fam.school_year {{ dbt_utils.group_by(4) }} ), @@ -60,12 +60,12 @@ rolling_final as ( us_intl, country, num_active_students, - sum(num_active_students) over( + sum(num_active_students_ytd) over( partition by school_year, us_intl, country - order by activity_month + order by activity_month rows between unbounded preceding and current row) as num_active_students_ytd from final From 007254fbbb9b412d4b8e435c9643a1110e82d63b Mon Sep 17 00:00:00 2001 From: Jordan Springer Date: Wed, 27 Nov 2024 14:44:15 +0000 Subject: [PATCH 4/5] stashing --- .../metrics/fct_monthly_active_students.sql | 29 +++++++++---------- 1 file changed, 13 insertions(+), 16 deletions(-) diff --git a/dbt/models/marts/metrics/fct_monthly_active_students.sql b/dbt/models/marts/metrics/fct_monthly_active_students.sql index bbb12db1..d69c3993 100644 --- a/dbt/models/marts/metrics/fct_monthly_active_students.sql +++ b/dbt/models/marts/metrics/fct_monthly_active_students.sql @@ -7,14 +7,10 @@ active_students as ( from {{ ref('dim_active_students') }} ), -school_years as ( - select * - from {{ref('int_school_years') }} -), - first_active_month as ( select - student_id, school_year, + student_id, + school_year, min(activity_month) as first_activity_month from active_students group by student_id, school_year @@ -22,16 +18,17 @@ first_active_month as ( combined as ( select - sy.school_year, - activity_month, - us_intl, - country, - student_id - from active_students - join school_years as sy - on active_students.activity_date - between sy.started_at - and sy.ended_at + 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 ( From ea7c69b950ce0a89396e0c1f123528f490adbd73 Mon Sep 17 00:00:00 2001 From: Jordan Springer Date: Wed, 27 Nov 2024 18:46:26 +0000 Subject: [PATCH 5/5] resolving final aggregation --- dbt/models/marts/metrics/_metrics__models.yml | 3 ++ .../metrics/fct_monthly_active_students.sql | 51 +++++++++++-------- 2 files changed, 33 insertions(+), 21 deletions(-) diff --git a/dbt/models/marts/metrics/_metrics__models.yml b/dbt/models/marts/metrics/_metrics__models.yml index 56df86e2..48ee814d 100644 --- a/dbt/models/marts/metrics/_metrics__models.yml +++ b/dbt/models/marts/metrics/_metrics__models.yml @@ -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: diff --git a/dbt/models/marts/metrics/fct_monthly_active_students.sql b/dbt/models/marts/metrics/fct_monthly_active_students.sql index d69c3993..9a3b1a39 100644 --- a/dbt/models/marts/metrics/fct_monthly_active_students.sql +++ b/dbt/models/marts/metrics/fct_monthly_active_students.sql @@ -1,9 +1,9 @@ --- Step 0: Stage data +-- Step 0: Stage data with active_students as ( select *, - date_trunc('month',activity_date) as activity_month + date_trunc('month', activity_date) as activity_month from {{ ref('dim_active_students') }} ), @@ -23,10 +23,9 @@ combined as ( acs.us_intl, acs.country, acs.student_id - - from active_students as acs + from active_students as acs left join first_active_month as fam - on acs.student_id = fam.student_id + on acs.student_id = fam.student_id and acs.school_year = fam.school_year and acs.activity_month >= fam.first_activity_month ), @@ -39,15 +38,24 @@ final as ( com.country, count(distinct com.student_id) as num_active_students, count(distinct case - when com.activity_month = fam.first_activity_month - then fam.student_id end) as num_active_students_ytd - - from combined as com - left join first_active_month as fam + 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 - - {{ dbt_utils.group_by(4) }} + 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, + num_active_students, + num_new_students + from final ), rolling_final as ( @@ -57,17 +65,18 @@ rolling_final as ( us_intl, country, num_active_students, - sum(num_active_students_ytd) over( + sum(num_new_students) over ( partition by - school_year, - us_intl, - country + school_year, + us_intl, + country order by activity_month - rows between unbounded preceding - and current row) as num_active_students_ytd - from final - {{ dbt_utils.group_by(5) }} ) + rows between unbounded preceding and current row + ) as num_active_students_ytd + from rolling_final_prep ) select * from rolling_final -order by activity_month desc \ No newline at end of file +order by + school_year, + activity_month desc \ No newline at end of file