Skip to content

Commit

Permalink
Feature/dim self paced pd activity (#140)
Browse files Browse the repository at this point in the history
  • Loading branch information
allison-code-dot-org authored Aug 16, 2024
2 parents 149f0ab + 32aed3a commit f6ab2df
Show file tree
Hide file tree
Showing 3 changed files with 309 additions and 0 deletions.
175 changes: 175 additions & 0 deletions dbt/dev/professional_development/dim_self_paced_pd_analysis.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,175 @@
with

active_teachers as (
select
teacher_id
, school_year
, course_name
, 1 as started
from {{ ref('int_active_sections') }}
)

, self_paced_pd_activity as (
select *
from {{ ref('dim_self_paced_pd_activity') }}
)

, teacher_history as(
select
t.course_name
, t.teacher_id
, first_value (
case
when t.started = 1 then t.school_year
else null
end ignore nulls)
over (
partition by t.teacher_id, t.course_name
order by left(t.school_year,4)
rows between unbounded preceding and unbounded following
) as first_teaching_sy
-- , count (
-- case
-- when t.started = 1 then t.school_year
-- else null
-- end ignore nulls
-- )
-- over (
-- partition by t.teacher_id, t.course_name
-- ) as num_sy_teaching
-- , first_value (
-- case
-- when t.started = 1 then t.school_id
-- else null
-- end ignore nulls)
-- over (
-- partition by t.teacher_id, t.course_name
-- order by left(t.school_year,4)
-- rows between unbounded preceding and unbounded following) as school_id_sy1
from active_teachers as t
)

, self_paced_metrics_1 as (
select distinct
teacher_id
, course_name_true
, script_name
, count (distinct script_id) as num_scripts
, count (distinct level_id) as num_levels
from self_paced_pd_activity
group by teacher_id
, course_name_true
, script_name
)

, self_paced_metrics_2 as (
select distinct
teacher_id
, course_name_true
, script_name
, min (level_created_at)
over (
partition by teacher_id, course_name_true) as start_dt
, max (level_created_at)
over (
partition by teacher_id, course_name_true) as end_dt
, min (level_created_school_year)
over (
partition by teacher_id, course_name_true) as first_self_paced_sy -- accounting for users who are have activity in multiple schools years for the same course
, last_value (script_id)
over (
partition by teacher_id, course_name_true
order by level_created_at
rows between unbounded preceding and unbounded following) as max_script_id
, last_value (script_name)
over (
partition by teacher_id, course_name_true
order by level_created_at
rows between unbounded preceding and unbounded following) as max_script_name
, last_value (level_id)
over (
partition by teacher_id, course_name_true, script_name
order by level_created_at
rows between unbounded preceding and unbounded following) as max_level_id
, last_value (level_name)
over (
partition by teacher_id, course_name_true, script_name
order by level_created_at
rows between unbounded preceding and unbounded following) as max_level_name
, last_value (stage_id)
over (
partition by teacher_id, course_name_true, script_name
order by level_created_at
rows between unbounded preceding and unbounded following) as max_stage_id
, last_value (stage_name)
over (
partition by teacher_id, course_name_true, script_name
order by level_created_at
rows between unbounded preceding and unbounded following) as max_stage_name
from self_paced_pd_activity
)

, self_paced_summary as (
select distinct
sp.teacher_id
, sp.course_name_true
, sp.course_name_implementation
, sp.studio_person_id
, m2.start_dt
, m2.end_dt
, m2.first_self_paced_sy
, sp.script_name
, m1.num_scripts
, m1.num_levels
, m2.max_script_id
, m2.max_script_name
, m2.max_stage_id
, m2.max_stage_name
, m2.max_level_id
, m2.max_level_name
from self_paced_pd_activity as sp
left join self_paced_metrics_1 as m1
on sp.teacher_id = m1.teacher_id
and sp.course_name_true = m1.course_name_true
and sp.script_name = m1.script_name
join self_paced_metrics_2 as m2
on sp.teacher_id = m2.teacher_id
and sp.course_name_true = m2.course_name_true
and sp.script_name = m2.script_name
)

select distinct
coalesce(th.teacher_id, sps.teacher_id) as teacher_id
, coalesce(th.course_name, sps.course_name) as course_name
, th.first_teaching_sy
, case
when sps.teacher_id is not null then 1
else 0
end as did_self_paced_pl
, sps.start_dt
, sps.end_dt
, sps.first_self_paced_sy
, sps.script_name
, sps.num_scripts
, sps.num_levels
, sps.max_script_id
, sps.max_script_name
, sps.max_stage_id
, sps.max_stage_name
, sps.max_level_id
, sps.max_level_name
, case
when th.first_teaching_sy is null
or sps.first_self_paced_sy is null
then null
when left(th.first_teaching_sy,4) > left(sps.first_self_paced_sy,4)
then 'after self-paced'
when left(th.first_teaching_sy,4) < left(sps.first_self_paced_sy,4)
then 'before self-paced'
when left(th.first_teaching_sy,4) = left(sps.first_self_paced_sy,4)
then 'same year as self-paced'
end as course_teaching_timing
from self_paced_summary as sps
left join teacher_history as th
on th.teacher_id = sps.teacher_id
and th.course_name = sps.course_name_implementation
26 changes: 26 additions & 0 deletions dbt/models/marts/teachers/_teachers__models.yml
Original file line number Diff line number Diff line change
@@ -1,6 +1,32 @@
version: 2

models:
- name: dim_self_paced_pd_activity
description: |
This model contains every teacher interaction with a self-paced PD level/script as well as variables that are helpful for segmentation.
columns:
- name: teacher_id
- name: level_id
- name: script_id
- name: stage_id
- name: unit
- name: script_name
- name: stage_name
- name: level_name
- name: level_created_at
- name: level_created_school_year
- name: best_result
- name: time_spent
- name: level_type
- name: school_id
- name: touch_rank
- name: level_number
- name: level_script_order
- name: stage_number
config:
tags: ['released']

- name: dim_active_teachers
description: |
This model serves as a prototype for a comprehensive view of daily teacher activities that roll into the 'active teacher' metric.
Expand Down
108 changes: 108 additions & 0 deletions dbt/models/marts/teachers/dim_self_paced_pd_activity.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
with
course_structure as (
select *
from {{ ref('dim_course_structure') }}
),

user_levels as (
select *
from {{ ref('stg_dashboard__user_levels') }}
),

teachers as (
select *
from {{ ref('dim_teachers') }}
),

levels as (
select *
from {{ ref('dim_levels') }}
),

school_years as (
select *
from {{ ref('int_school_years') }}
),

self_paced_scripts as (
select distinct
cs.level_id
, cs.script_id
, cs.stage_id
, cs.unit
, cs.script_name
, cs.stage_name
, cs.level_name
, cs.stage_number
, cs.level_number
, cs.level_script_order
, cs.course_name_true
, case
when cs.script_name ilike 'k5-onlinepd%' then 'csf'
when cs.script_name like 'self-paced-pl-k5%' then 'csf'
when cs.script_name like 'self-paced-pl-csd%' then 'csd'
when cs.script_name like 'self-paced-pl-csp%' then 'csp'
when cs.script_name like 'self-paced-pl-csc%' then 'csc'
when cs.script_name like 'self-paced-pl-aiml%' then 'csd'
when cs.script_name like 'self-paced-pl-physical%' then 'csd'
when cs.script_name like 'self-paced-pl-microbit%' then 'csd'
when cs.script_name like 'kodea-pd%' then 'csf'
when cs.script_name like 'self-paced-pl-ai-101%' then 'ai_teachers'
when cs.script_name like 'k5howaimakesdecisions' then 'ai_k5'
when cs.script_name like '%foundations%' then 'foundations'
when cs.course_name_true in ('csf self paced pl') then 'csf'
end as course_name_implementation
from course_structure cs
where
(
cs.participant_audience = 'teacher'
and cs.instruction_type = 'self_paced'
and cs.published_state in ('stable', 'beta')
)
and cs.script_name not in ('alltheselfpacedplthings')
and cs.course_name_true not like 'pd workshop activity%' -- csa's self-paced pl is asynchronous work for facilitator-led pd workshops
)
select
ul.user_id as teacher_id
, ul.level_id
, ul.script_id
, sps.stage_id
, sps.unit
, sps.script_name
, sps.stage_name
, sps.level_name
, sps.course_name_true as course_name
, sps.course_name_implementation
, ul.created_at as level_created_at
, sy.school_year as level_created_school_year
, ul.best_result
, ul.time_spent
, l.level_type
-- , t.studio_person_id
-- , t.gender
-- , t.races
-- , t.is_urg
, t.school_id
, rank ()
over (
partition by ul.user_id
order by ul.created_at asc) as touch_rank
, sps.level_number
, sps.level_script_order
, sps.stage_number
-- , t.created_at as account_created_at

from self_paced_scripts as sps

join user_levels as ul
on sps.level_id = ul.level_id
and sps.script_id = ul.script_id

join levels as l
on ul.level_id = l.level_id

join teachers as t
on ul.user_id = t.teacher_id

join school_years as sy
on ul.created_at between sy.started_at and sy.ended_at

0 comments on commit f6ab2df

Please sign in to comment.