diff --git a/dbt/archive/int_application_status_times.sql b/dbt/archive/int_application_status_times.sql new file mode 100644 index 00000000..ce6aea84 --- /dev/null +++ b/dbt/archive/int_application_status_times.sql @@ -0,0 +1,35 @@ +with + +pd_applications_status_logs as ( + select * + from {{ ref('stg_dashboard_pii__pd_applications_status_logs') }} +), + +days_in_status as ( + select + logs_1.pd_application_id + , logs_1.application_status + , case + when logs_2.changed_status_dt is not null + then datediff('day', logs_1.changed_status_dt, logs_2.changed_status_dt) + else datediff('day', logs_1.changed_status_dt, current_date) + end as days_in_status + from pd_applications_status_logs as logs_1 + left join pd_applications_status_logs as logs_2 + on logs_1.change_order = logs_2.change_order - 1 + and logs_1.pd_application_id = logs_2.pd_application_id + order by logs_1.pd_application_id +) + +select * +from days_in_status +pivot ( + avg(days_in_status) + for application_status in ( + 'pending' as days_in_pending + ,'unreviewed' as days_in_unreviewed + ,'incomplete' as days_in_incomplete + ,'pending_space_availability' as days_in_pending_space_availability + ,'awaiting_admin_approval' as days_in_awaiting_admin_approval + ) +) \ No newline at end of file diff --git a/dbt/archive/pd_funnel_6_12.sql b/dbt/archive/pd_funnel_6_12.sql new file mode 100644 index 00000000..81c5775b --- /dev/null +++ b/dbt/archive/pd_funnel_6_12.sql @@ -0,0 +1,166 @@ +with + +pd_applications as ( + select * + from {{ ref('stg_dashboard_pii__pd_applications') }} +), + +pd_enrollments as ( + select + pd_enrollment_id + , pd_workshop_id + , teacher_id + , enrolled_at + from {{ ref('stg_dashboard_pii__pd_enrollments') }} + where teacher_id is not null +), + +pd_attendances as ( + select + pd_attendance_id + , pd_session_id + , teacher_id + from {{ ref('stg_dashboard_pii__pd_attendances') }} +), + +pd_sessions as ( + select + pd_session_id + , pd_workshop_id + , school_year + , cal_year + from {{ ref('stg_dashboard_pii__pd_sessions') }} +), + +pd_workshops as ( + select + pd_workshop_id + , organizer_id + , school_year + , cal_year + , course_name + , subject + , regional_partner_id + from {{ ref('stg_dashboard_pii__pd_workshops') }} +), + +int_application_status_times as ( + select * + from {{ ref('int_application_status_times') }} +), + +regional_partners as ( + select * + from {{ ref('stg_dashboard_pii__regional_partners') }} +), + +enrollments_with_course as ( + select + pde.* + , pdw.course_name + , pdw.school_year + , pdw.regional_partner_id + from pd_enrollments as pde + join pd_workshops as pdw + on pde.pd_workshop_id = pdw.pd_workshop_id + where lower(pdw.subject) = '5-day summer' + and pdw.course_name in ('csd', 'csp', 'csa') +), + +attendances_by_workshop as ( + select + att.teacher_id + , pdw.course_name + , pdw.school_year + , count(distinct att.pd_session_id) as num_sessions_attended + from pd_attendances as att + left join pd_sessions as pds + on att.pd_session_id = pds.pd_session_id + left join pd_workshops as pdw + on pds.pd_workshop_id = pdw.pd_workshop_id + where lower(pdw.subject) = '5-day summer' + and pdw.course_name in ('csd', 'csp', 'csa') + group by 1,2,3 +), + +all_in_funnel as ( + select distinct + teacher_id + , course_name + , school_year + from pd_applications + union + select distinct + teacher_id + , course_name + , school_year + from enrollments_with_course +) + +select + af.teacher_id + , coalesce (pde.regional_partner_id, pda.regional_partner_id) as regional_partner_id + , af.school_year + , af.course_name + , case + when pda.teacher_id is not null then 1 + else 0 + end as applied + , coalesce(pda.accepted,0) as accepted + , case + when pde.teacher_id is not null then 1 + else 0 + end as enrolled + , case + when att.num_sessions_attended > 0 then 1 + else 0 + end as attended + , coalesce(att.num_sessions_attended, 0) as num_sessions_attended + , case + when att.num_sessions_attended > 3 then 1 + else 0 + end as trained + , pda.current_status + , datediff(day, pda.applied_at, pda.accepted_at) as days_applied_accepted + , datediff(day, pda.applied_at, pde.enrolled_at) as days_applied_enrolled + , datediff(day, pda.accepted_at, pde.enrolled_at) as days_accepted_enrolled + , st.days_in_pending + , st.days_in_unreviewed + , st.days_in_incomplete + , st.days_in_pending_space_availability + , st.days_in_awaiting_admin_approval + , rp.urg_guardrail_pct + , rp.frl_guardrail_pct +from all_in_funnel as af +left join pd_applications as pda + on af.teacher_id = pda.teacher_id + and af.course_name = pda.course_name + and af.school_year = pda.school_year +left join int_application_status_times as st + on pda.pd_application_id = st.pd_application_id +left join enrollments_with_course as pde + on af.teacher_id = pde.teacher_id + and af.course_name = pde.course_name + and af.school_year = pde.school_year +left join attendances_by_workshop as att + on af.teacher_id = att.teacher_id + and af.course_name = att.course_name + and af.school_year = att.school_year +left join regional_partners as rp + on rp.regional_partner_id = + coalesce( + pde.regional_partner_id + , pda.regional_partner_id + ) +where af.course_name in ('csd', 'csp', 'csa') + + + + + + + + + + + diff --git a/dbt/archive/pd_funnel_K_5.sql b/dbt/archive/pd_funnel_K_5.sql new file mode 100644 index 00000000..cb1e6dd8 --- /dev/null +++ b/dbt/archive/pd_funnel_K_5.sql @@ -0,0 +1,84 @@ +with +pd_enrollments as ( + select + pd_enrollment_id + , pd_workshop_id + , teacher_id + , enrolled_at + from {{ ref('stg_dashboard_pii__pd_enrollments') }} + where teacher_id is not null +), + +pd_attendances as ( + select + pd_attendance_id + , pd_session_id + , teacher_id + from {{ ref('stg_dashboard_pii__pd_attendances') }} +), + +pd_sessions as ( + select + pd_session_id + , pd_workshop_id + , school_year + , cal_year + from {{ ref('stg_dashboard_pii__pd_sessions') }} +), + +pd_workshops as ( + select + pd_workshop_id + , organizer_id + , school_year + , cal_year + , course_name + , subject + , regional_partner_id + from {{ ref('stg_dashboard_pii__pd_workshops') }} +), + +enrollments_with_course as ( + select + pde.* + , pdw.course_name + , pdw.school_year + , pdw.regional_partner_id + from pd_enrollments as pde + join pd_workshops as pdw + on pde.pd_workshop_id = pdw.pd_workshop_id + where lower(pdw.subject) in ('intro workshop', 'intro', 'deep dive', 'district') + and pdw.course_name in ('csf') +), + +attendances_by_workshop as ( + select + att.teacher_id + , pdw.course_name + , pdw.school_year + , count(distinct att.pd_session_id) as num_sessions_attended + from pd_attendances as att + left join pd_sessions as pds + on att.pd_session_id = pds.pd_session_id + left join pd_workshops as pdw + on pds.pd_workshop_id = pdw.pd_workshop_id + where lower(pdw.subject) in ('intro workshop', 'intro', 'deep dive', 'district') + and pdw.course_name in ('csf') + group by 1,2,3 +) + +select + pde.teacher_id + , pde.regional_partner_id + , pde.school_year + , pde.course_name + , case + when att.num_sessions_attended > 0 then 1 + else 0 + end as trained +from enrollments_with_course as pde +left join attendances_by_workshop as att + on pde.teacher_id = att.teacher_id + and pde.course_name = att.course_name + and pde.school_year = att.school_year +where pde.course_name in ('csf') \ No newline at end of file diff --git a/dbt/models/intermediate/_intermediate__models.yml b/dbt/models/intermediate/_intermediate__models.yml index 9adf7738..14bafe0a 100644 --- a/dbt/models/intermediate/_intermediate__models.yml +++ b/dbt/models/intermediate/_intermediate__models.yml @@ -1,6 +1,22 @@ version: 2 -models: +models: + - name: int_application_status_times + description: | + For every application to PD, this model gives the # days spent in each application status until they are in a final state (e.g. accepted, withdrawn, declined) + columns: + - name: pd_application_id + - name: days_in_pending + description: the number of days the application was in the status of "pending" + - name: days_in_unreviewed + description: the number of days the application was in the status of "unreviewed" + - name: days_in_incomplete + description: the number of days the application was in the status of "incomplete" + - name: days_in_pending_space_availability + description: the number of days the application was in the status of "pending space availability" + - name: days_in_awaiting_admin_approval + description: the number of days the application was in the status of "awaiting admin approval" + - name: int_ap_agg_exam_results_union_agg_school_level description: | This intermediate model unions together: diff --git a/dbt/models/marts/districts/dim_districts.sql b/dbt/models/marts/districts/dim_districts.sql index 7d806ac7..1b0f4077 100644 --- a/dbt/models/marts/districts/dim_districts.sql +++ b/dbt/models/marts/districts/dim_districts.sql @@ -12,6 +12,16 @@ school_districts as ( from {{ ref('stg_dashboard__school_districts') }} ), +regional_partners as ( + select * + from {{ ref('dim_regional_partners') }} +), + +rp_mappings as ( + select * + from {{ ref('stg_dashboard_pii__pd_regional_partner_mappings') }} +), + combined as ( select school_districts.school_district_id, @@ -21,6 +31,10 @@ combined as ( school_districts.school_district_zip, school_districts.last_known_school_year_open, + --regional partner association + rp_mappings.regional_partner_id, + regional_partners.regional_partner_name, + -- school aggregations count(distinct dim_schools.school_id) as num_schools, sum(dim_schools.is_stage_el) as num_schools_stage_el, @@ -44,8 +58,19 @@ combined as ( from dim_schools left join school_districts on dim_schools.school_district_id = school_districts.school_district_id + left join rp_mappings + on ( + school_districts.school_district_zip = rp_mappings.zip_code + or ( + rp_mappings.zip_code is null + and + school_districts.school_district_state = rp_mappings.state + ) + ) + left join regional_partners + on regional_partners.regional_partner_id = rp_mappings.regional_partner_id where dim_schools.school_district_id is not null - {{ dbt_utils.group_by(6) }} + {{ dbt_utils.group_by(8) }} ) select * diff --git a/dbt/models/marts/professional_development/_professional_development__models.yml b/dbt/models/marts/professional_development/_professional_development__models.yml new file mode 100644 index 00000000..ff8bdac5 --- /dev/null +++ b/dbt/models/marts/professional_development/_professional_development__models.yml @@ -0,0 +1,68 @@ +version: 2 + +models: + - name: dim_pl_activity + description: | + this model has a row for every teacher who touches self-paced or attends facilitated PL for a particular topic (or course) in a given school year. + columns: + - name: teacher_id + data_tests: + - not_null + description: unique ID for the teacher + - name: school_year + description: the school year associated with the teacher's PL activity or attendance + - name: pl_type + description: facilitated or self-paced; note that some facilitated workshops include self-paced components, and that teacher would have rows for both self-paced and facilitated activity + - name: pl_workshop_id + description: the workshop associated with the facilitated activity + - name: pl_organizer_id + description: unique ID for the organizer (if this organizer is a regional partner, they will also have a regional_partner_id) + - name: workshop_regional_partner_id + description: the ID of the regional partner who hosted the workshop + - name: district_regional_partner_id + description: the ID of the regional partner associated with the district of the teacher's school + - name: is_byow + description: 1 if the workshop attended is "build your own workshop", 0 otherwise + - name: topic + description: the topic (in the case of BYOW) or course name (in the case of non-BYOW or self-paced) associated with the PL activity + - name: grade_band + description: the grade band associated with the topic + - name: school_id + description: the school_id associated with the teacher's code.org account + - name: school_district_id + description: the school district id associated with the teacher's school in their account + - name: num_levels + description: the number of self-paced levels the teacher touched, null for facilitated PL engagement + - name: num_hours + description: the number of hours of training the teacher attended, calculated as the sum of all PL session durations that they have an attendance record for + + - name: dim_pl_engagement + description: | + this model has a row for every teacher who engages in any PL within a given grade band in a given school year and assigns an engagement level to their record. This model also is used to measure impact and effectiveness of PL engagement (implementation and sustained implementation) + columns: + - name: teacher_id + data_tests: + - not_null + - name: school_year + description: the school year associated with the PL engagement + - name: grade_band + description: the grade band associated with the topics/ courses of the PL engagement + - name: school_id + description: the school_id associated with the teacher's code.org account + - name: school_district_id + description: the school district id associated with the teacher's school in their account + - name: total_hours + description: the total number of hours the teacher spent at a facilitated training for that grade band + - name: total_levels + description: the total number of levels the teacher touched of self-paced PL associated with that grade band + - name: pl_engagement_level + description: low (< 37 levels touched and 0 facilitated hours), medium (between 1 and 8 facilitated hours or between 37 - 65 levels touched), or high (>8 facilitated hours or > 65 levels touched) + - name: includes_facilitated + description: 1 if the teacher did any amount of facilitated training for that grade band in that school year , 0 otherwise + - name: topics_touched + description: comma separated list of topics (or courses) touched in that school year/ grade band + - name: implemented + description: 1 if the teacher was an in-classroom teacher either in that same school year as training or the following school year + - name: sustained + description: 1 if the teacher was n in-classroom teacher for the year after implementing + \ No newline at end of file diff --git a/dbt/models/marts/teachers/dim_global_teacher_roster.sql b/dbt/models/marts/professional_development/dim_global_teacher_roster.sql similarity index 100% rename from dbt/models/marts/teachers/dim_global_teacher_roster.sql rename to dbt/models/marts/professional_development/dim_global_teacher_roster.sql diff --git a/dbt/models/marts/teachers/dim_global_trained_teacher_script_progress.sql b/dbt/models/marts/professional_development/dim_global_trained_teacher_script_progress.sql similarity index 100% rename from dbt/models/marts/teachers/dim_global_trained_teacher_script_progress.sql rename to dbt/models/marts/professional_development/dim_global_trained_teacher_script_progress.sql diff --git a/dbt/models/marts/professional_development/dim_pl_activity.sql b/dbt/models/marts/professional_development/dim_pl_activity.sql new file mode 100644 index 00000000..98195200 --- /dev/null +++ b/dbt/models/marts/professional_development/dim_pl_activity.sql @@ -0,0 +1,197 @@ +with + +self_paced_activity as ( + select + teacher_id, + level_created_school_year as school_year, + course_name_implementation as topic, + 'self_paced' as pd_type, + case + when content_area = 'self_paced_pl_k_5' then 'k_5' + when content_area = 'self_paced_pl_6_8' then '6_8' + when content_area = 'self_paced_pl_9_12' then '9_12' + when content_area = 'skills_focused_self_paced_pl' then 'skills_focused' + else 'other' + end as grade_band, + -- , min(level_created_dt) as first_activity_at + -- , max(level_created_dt) as last_activity_at + count(distinct level_script_id) as num_levels + from {{ ref('dim_self_paced_pd_activity') }} + {{ dbt_utils.group_by(5) }} +), + +teacher_schools_historical as ( + select * + from {{ ref('int_teacher_schools_historical') }} +), + +schools as ( + select * + from {{ ref('dim_schools') }} +), + +districts as ( + select * + from {{ ref('dim_districts') }} +), + +pd_attendances as ( + select + pd_attendance_id + , pd_session_id + , teacher_id + , school_year + from {{ ref('stg_dashboard_pii__pd_attendances') }} + where teacher_id is not null +), + +pd_sessions as ( + select + pd_session_id + , pd_workshop_id + , school_year + , num_hours + from {{ ref('stg_dashboard_pii__pd_sessions') }} +), + +pd_workshops as ( + select + pd_workshop_id + , organizer_id + , school_year + , course_name + , subject + , regional_partner_id + , is_byow + from {{ ref('stg_dashboard_pii__pd_workshops') }} +), + +course_offerings as ( + select * + from {{ ref('stg_dashboard__course_offerings') }} +), + +course_offerings_pd_workshops as ( + select * + from {{ ref('stg_dashboard_pii__course_offerings_pd_workshops') }} +), + +course_structure as ( + select + *, + case + when content_area = 'curriculum_k_5' then 'k_5' + when content_area = 'curriculum_6_8' then '6_8' + when content_area = 'curriculum_9_12' then '9_12' + when content_area = 'self_paced_pl_k_5' then 'k_5' + when content_area = 'self_paced_pl_6_8' then '6_8' + when content_area = 'self_paced_pl_9_12' then '9_12' + when content_area = 'skills_focused_self_paced_pl' then 'skills_focused' + else 'other' + end as grade_band + from {{ ref('dim_course_structure') }} + where content_area != 'other' +), + +regional_partners as ( + select * + from {{ ref('dim_regional_partners') }} +), + +course_scripts as ( + select * + from {{ ref('stg_dashboard__course_scripts') }} +), + +content_area_mapping as ( + select distinct + wco.course_offering_id, + cs.grade_band + from course_offerings_pd_workshops wco + join course_offerings co + on wco.course_offering_id = co.course_offering_id + left join course_structure cs on co.key = cs.family_name +), + +facilitated_pd as ( + select distinct + pda.teacher_id, + pdw.school_year, + 'facilitated' as pl_type, + pdw.pd_workshop_id as pl_workshop_id, + pdw.organizer_id as pl_organizer_id, + pdw.regional_partner_id as workshop_regional_partner_id, + districts.regional_partner_id as district_regional_partner_id, + pdw.is_byow, + case + when pdw.course_name = 'build your own workshop' then co.display_name + else pdw.course_name + end as topic, + coalesce(cam.grade_band, cs.grade_band) as grade_band, + tsh.school_id, + schools.school_district_id, + cast(null as bigint) as num_levels, + sum(pds.num_hours) as num_hours + +from pd_attendances pda +join pd_sessions pds + on pda.pd_session_id = pds.pd_session_id +join pd_workshops pdw + on pds.pd_workshop_id = pdw.pd_workshop_id +left join course_structure cs + on pdw.course_name = cs.course_name +left join course_offerings_pd_workshops copw + on pdw.pd_workshop_id = copw.pd_workshop_id +left join content_area_mapping cam + on copw.course_offering_id = cam.course_offering_id +left join course_offerings co + on copw.course_offering_id = co.course_offering_id +left join teacher_schools_historical tsh + on pda.teacher_id = tsh.teacher_id + and pda.school_year = tsh.started_at_sy +left join schools + on tsh.school_id = schools.school_id +left join districts + on schools.school_district_id = districts.school_district_id +{{ dbt_utils.group_by(13) }} +), + +self_paced_pd as ( + select distinct + spa.teacher_id, + spa.school_year, + spa.pd_type as pl_type, + cast(null as bigint) as pl_workshop_id, + cast(null as bigint) as pl_organizer_id, + cast(null as bigint) as workshop_regional_partner_id, + districts.regional_partner_id as district_regional_partner_id, + cast(null as bigint) as is_byow, + spa.topic, + spa.grade_band, + tsh.school_id, + schools.school_district_id, + spa.num_levels, + cast(null as bigint) as num_hours + + from self_paced_activity spa + left join teacher_schools_historical tsh + on spa.teacher_id = tsh.teacher_id + and spa.school_year = tsh.started_at_sy + left join schools + on tsh.school_id = schools.school_id + left join districts + on schools.school_district_id = districts.school_district_id +), + +combined as ( + select * + from facilitated_pd + + union + + select * + from self_paced_pd +) + +select * +from combined diff --git a/dbt/models/marts/professional_development/dim_pl_engagement.sql b/dbt/models/marts/professional_development/dim_pl_engagement.sql new file mode 100644 index 00000000..cc39745a --- /dev/null +++ b/dbt/models/marts/professional_development/dim_pl_engagement.sql @@ -0,0 +1,82 @@ +with + +pl_activity as ( + select * + from {{ ref('dim_pl_activity') }} +), + +school_years as ( + select * + from {{ ref('int_school_years') }} +), + +active_teachers as ( + select * + from {{ ref('dim_teacher_status') }} + where status like 'active%' +), + +active_teachers_sy_int as ( + select + active_teachers.*, + school_years.school_year_int + from active_teachers + join school_years + on active_teachers.school_year = school_years.school_year +), + +pl_with_engagement as ( + select + pl_activity.teacher_id, + pl_activity.school_year, + school_years.school_year_int, + pl_activity.grade_band, + pl_activity.school_id, + pl_activity.school_district_id, + sum(pl_activity.num_hours) as total_hours, + sum(pl_activity.num_levels) as total_levels, + + case + when coalesce(sum(pl_activity.num_hours), 0) = 0 and coalesce(sum(pl_activity.num_levels), 0) < 37 then 'low' + when (sum(pl_activity.num_hours) between 1 and 8) or (sum(pl_activity.num_levels) between 37 and 65) then 'medium' + when (sum(pl_activity.num_hours) > 8) or (sum(pl_activity.num_levels) > 65) then 'high' + else null + end as pl_engagement_level, + + case + when sum(pl_activity.num_hours) > 0 then 1 + else 0 + end as includes_facilitated, + + listagg(distinct pl_activity.topic, ', ') within group (order by pl_activity.teacher_id, pl_activity.school_year, pl_activity.grade_band) as topics_touched + from pl_activity + join school_years + on pl_activity.school_year = school_years.school_year + group by 1,2,3,4,5,6 +) + +select + pl.*, + case + when act_1.teacher_id is not null or act_2.teacher_id is not null then 1 + else 0 + end as implemented, + case + when act_1.teacher_id is not null and act_2.teacher_id is not null then 1 + when act_2.teacher_id is not null and act_3.teacher_id is not null then 1 + else 0 + end as sustained +from pl_with_engagement pl +left join active_teachers_sy_int act_1 + on pl.teacher_id = act_1.teacher_id + and pl.school_year_int = act_1.school_year_int +left join active_teachers_sy_int act_2 + on pl.teacher_id = act_2.teacher_id + and pl.school_year_int + 1 = act_2.school_year_int +left join active_teachers_sy_int act_3 + on pl.teacher_id = act_3.teacher_id + and pl.school_year_int + 2 = act_3.school_year_int + + + + diff --git a/dbt/models/marts/professional_development/dim_regional_partners.sql b/dbt/models/marts/professional_development/dim_regional_partners.sql new file mode 100644 index 00000000..5f94b99e --- /dev/null +++ b/dbt/models/marts/professional_development/dim_regional_partners.sql @@ -0,0 +1,22 @@ +with + +regional_partners as ( + select * + from {{ ref('stg_dashboard_pii__regional_partners') }} +), + +rp_mappings as ( + select * + from {{ ref('stg_dashboard_pii__pd_regional_partner_mappings') }} +) + +select + regional_partners.regional_partner_id + , regional_partners.regional_partner_name + --, regional_partners.is_urban # questioning the accuracy of this field + , coalesce(rp_mappings.state, nullif(regional_partners.state, '')) as state + --, rp_mappings.zip_code + --, is_active - # questioning the accuracy of this field +from rp_mappings +left join regional_partners + on rp_mappings.regional_partner_id = regional_partners.regional_partner_id diff --git a/dbt/models/marts/teachers/dim_self_paced_pd_activity.sql b/dbt/models/marts/professional_development/dim_self_paced_pd_activity.sql similarity index 97% rename from dbt/models/marts/teachers/dim_self_paced_pd_activity.sql rename to dbt/models/marts/professional_development/dim_self_paced_pd_activity.sql index 2f6b4c84..1f8294aa 100644 --- a/dbt/models/marts/teachers/dim_self_paced_pd_activity.sql +++ b/dbt/models/marts/professional_development/dim_self_paced_pd_activity.sql @@ -90,6 +90,7 @@ select distinct , sps.course_name_implementation , ul.created_date as level_created_dt , sy.school_year as level_created_school_year + , extract('year' from ul.created_date) as level_created_cal_year , ul.best_result , ul.time_spent_minutes as time_spent , l.level_type diff --git a/dbt/models/staging/dashboard/_dashboard__sources.yml b/dbt/models/staging/dashboard/_dashboard__sources.yml index 926804ac..702c5a06 100644 --- a/dbt/models/staging/dashboard/_dashboard__sources.yml +++ b/dbt/models/staging/dashboard/_dashboard__sources.yml @@ -11,6 +11,7 @@ sources: - name: census_submissions - name: contained_level_answers - name: contained_levels + - name: course_offerings - name: census_summaries - name: course_scripts - name: courses diff --git a/dbt/models/staging/dashboard/base/base_dashboard__course_offerings.sql b/dbt/models/staging/dashboard/base/base_dashboard__course_offerings.sql new file mode 100644 index 00000000..6fac01f6 --- /dev/null +++ b/dbt/models/staging/dashboard/base/base_dashboard__course_offerings.sql @@ -0,0 +1,29 @@ +with +source as ( + select + id, + key, + display_name, + created_at, + updated_at, + is_featured, + assignable, + curriculum_type, + marketing_initiative, + grade_levels, + header, + image, + cs_topic, + school_subject, + device_compatibility, + description, + professional_learning_program, + video, + published_date, + self_paced_pl_course_offering_id, + ai_teaching_assistant_available + from {{ source('dashboard', 'course_offerings') }} +) + +select * +from source \ No newline at end of file diff --git a/dbt/models/staging/dashboard/stg_dashboard__course_offerings.sql b/dbt/models/staging/dashboard/stg_dashboard__course_offerings.sql new file mode 100644 index 00000000..d684e0cb --- /dev/null +++ b/dbt/models/staging/dashboard/stg_dashboard__course_offerings.sql @@ -0,0 +1,36 @@ +with + +base as ( + select * + from {{ ref('base_dashboard__course_offerings') }} +), + +renamed as ( + select + id as course_offering_id, + key, + lower(display_name) as display_name, + -- created_at, + -- updated_at, + is_featured, + assignable, + lower(curriculum_type) as curriculum_type, + --marketing_initiative) + grade_levels, + + -- header, + -- image, + lower(cs_topic) as cs_topic, + --lower(school_subject) as school_subject, + --device_compatibility, + --description, + --professional_learning_program, + -- video, + date_trunc('day', published_date) as published_at, + --self_paced_pl_course_offering_id, + ai_teaching_assistant_available + from base +) + +select * +from renamed \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/_dashboard_pii__models.yml b/dbt/models/staging/dashboard_pii/_dashboard_pii__models.yml index 6c9508f4..ccd072dc 100644 --- a/dbt/models/staging/dashboard_pii/_dashboard_pii__models.yml +++ b/dbt/models/staging/dashboard_pii/_dashboard_pii__models.yml @@ -1,6 +1,10 @@ version: 2 models: + - name: stg_dashboard_pii__pd_applications_status_logs + description: | + Records time in each status by application id + - name: stg_dashboard_pii__projects description: | Records of all user's projects diff --git a/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml b/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml index cd441759..9e8be3e2 100644 --- a/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml +++ b/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml @@ -5,6 +5,7 @@ sources: database: dashboard schema: dashboard_production_pii tables: + - name: course_offerings_pd_workshops - name: foorm_forms - name: foorm_libraries - name: foorm_library_questions @@ -13,6 +14,7 @@ sources: - name: foorm_submissions - name: level_sources - name: pd_applications + - name: pd_applications_status_logs - name: pd_attendances - name: pd_enrollments - name: pd_international_opt_ins diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__course_offerings_pd_workshops.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__course_offerings_pd_workshops.sql new file mode 100644 index 00000000..9e46e25b --- /dev/null +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__course_offerings_pd_workshops.sql @@ -0,0 +1,12 @@ +with +source as ( + select + pd_workshop_id, + course_offering_id, + created_at, + updated_at + from {{ source('dashboard_pii', 'course_offerings_pd_workshops') }} +) + +select * +from source \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications.sql index d87c8b14..63a6cfde 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications.sql @@ -7,25 +7,24 @@ source as ( renamed as ( select - id as pd_application_id, - user_id, - type, - application_year, - application_type, - regional_partner_id, - status, - locked_at, + id as pd_application_id + , user_id as teacher_id + , application_year + , application_type + , regional_partner_id + , status as current_status + , locked_at -- notes, - -- form_data, - created_at, - updated_at, - course, - response_scores, - application_guid, - accepted_at, - -- properties, - status_timestamp_change_log, - applied_at + , form_data + , created_at + , updated_at + , course as course_name + , response_scores + , application_guid + , accepted_at + , properties + , status_timestamp_change_log + , applied_at from source ) diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications_status_logs.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications_status_logs.sql new file mode 100644 index 00000000..fae5136e --- /dev/null +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications_status_logs.sql @@ -0,0 +1,13 @@ +with +source as ( + select * + from {{ source('dashboard_pii', 'pd_applications_status_logs') }} +) + +select + id as application_status_id + , pd_application_id + , status as application_status + , timestamp as changed_status_dt + , position as change_order +from source \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_attendances.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_attendances.sql index 21f11554..79a9a121 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_attendances.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_attendances.sql @@ -2,7 +2,7 @@ with source as ( select * from {{ source('dashboard_pii', 'pd_attendances') }} - where not deleted_at + where deleted_at is null ), renamed as ( diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_enrollments.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_enrollments.sql index ce380bcd..870c476a 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_enrollments.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_enrollments.sql @@ -2,27 +2,27 @@ with source as ( select * from {{ source('dashboard_pii', 'pd_enrollments') }} - where not deleted_at + where deleted_at is null ), renamed as ( select - id as pd_enrollment_id, - pd_workshop_id, - name, + id as pd_enrollment_id + , pd_workshop_id + , name -- first_name, -- last_name, -- email, - created_at, - updated_at, - school, - code, - user_id, - survey_sent_at, - completed_survey_id, - school_info_id, - -- properties, - application_id + , created_at as enrolled_at + , updated_at + , school as user_entered_school + , code + , user_id as teacher_id + , survey_sent_at as survey_sent_dt + , completed_survey_id + , school_info_id + , properties + , application_id from source ) diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_regional_partner_mappings.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_regional_partner_mappings.sql index 3a487ef1..56e3ac20 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_regional_partner_mappings.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_regional_partner_mappings.sql @@ -2,7 +2,7 @@ with source as ( select * from {{ source('dashboard_pii', 'pd_regional_partner_mappings') }} - where not deleted_at + where deleted_at is null ), renamed as ( diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_sessions.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_sessions.sql index 6d53631e..08747f8b 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_sessions.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_sessions.sql @@ -2,7 +2,7 @@ with source as ( select * from {{ source('dashboard_pii', 'pd_sessions') }} - where not deleted_at + where deleted_at is null ), renamed as ( diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_workshops.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_workshops.sql index d4465b02..0a9ef336 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_workshops.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_workshops.sql @@ -2,7 +2,7 @@ with source as ( select * from {{ source('dashboard_pii', 'pd_workshops') }} - where not deleted_at + where deleted_at is null ), renamed as ( diff --git a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__regional_partners.sql b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__regional_partners.sql index 839e72fe..6831301d 100644 --- a/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__regional_partners.sql +++ b/dbt/models/staging/dashboard_pii/base/base_dashboard_pii__regional_partners.sql @@ -2,7 +2,7 @@ with source as ( select * from {{ source('dashboard_pii', 'regional_partners') }} - where not deleted_at + where deleted_at is null ), renamed as ( @@ -21,7 +21,7 @@ renamed as ( -- notes, created_at, updated_at, - -- properties, + properties, is_active from source ) diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__course_offerings_pd_workshops.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__course_offerings_pd_workshops.sql new file mode 100644 index 00000000..83fa78f9 --- /dev/null +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__course_offerings_pd_workshops.sql @@ -0,0 +1,13 @@ +with + +base as ( + select + pd_workshop_id, + course_offering_id, + created_at, + updated_at + from {{ ref('base_dashboard_pii__course_offerings_pd_workshops') }} +) + +select * +from base \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications.sql index 26ffc842..eb0e5aff 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications.sql @@ -4,5 +4,135 @@ pd_applications as ( from {{ ref('base_dashboard_pii__pd_applications') }} ) -select * +select + pd_application_id + , application_guid + , teacher_id + , application_type + , left(application_year,4) as cal_year + , left(application_year,5) + substring(application_year, 8, 3) as school_year + , regional_partner_id + , case + when + current_status like '%accepted%' + or current_status in ( + 'paid' + ,'registration_sent' + ) then 'accepted' + else current_status + end as current_status + , course_name + , applied_at + , accepted_at + , case + when json_extract_path_text( + properties,'principal_approval_not_required' + ) = '' then 1 + else 0 + end as admin_approval_required + , case + when json_extract_path_text( + form_data,'doYouApprove' + ) = 'Yes' then 1 + else 0 + end as admin_approval_received + , case + when + teacher_id is not null + and applied_at is not null + then 1 + else 0 + end as submitted + , case + when + teacher_id is not null + and applied_at is not null + then 'app submitted' + when + teacher_id is not null + and applied_at is null + then 'app saved' + else 'unknown' + end as submission_status + , case + when current_status in ( + 'accepted' + ,'accepted_no_cost_registration' + ,'accepted_not_notified' + ,'accepted_notified_by_partner' + ,'paid','registration_sent') + then 1 + else 0 + end as accepted + , json_extract_path_text(form_data, 'school') as user_entered_school + , status_timestamp_change_log + , json_extract_path_text( + json_extract_path_text( + response_scores + , 'meets_scholarship_criteria_scores' + ) + , 'free_lunch_percent' + ) as scholarship_frl + , json_extract_path_text( + json_extract_path_text( + response_scores + , 'meets_scholarship_criteria_scores' + ) + ,'underrepresented_minority_percent' + ) as scholarship_urg + , json_extract_path_text(form_data, 'howHeard') as how_heard + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Code.org website%' then 1 + else 0 + end as how_heard_code_website + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Code.org email%' then 1 + else 0 + end as how_heard_email + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Regional Partner website%' then 1 + else 0 + end as how_heard_rp_website + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Regional Partner email%' then 1 + else 0 + end as how_heard_rp_email + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Regional Partner event or workshop%' then 1 + else 0 + end as how_heard_rp_event_workshop + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Teacher%' then 1 + else 0 + end as how_heard_teacher + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%District administrator%' then 1 + else 0 + end as how_heard_administrator + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Conference%' then 1 + else 0 + end as how_heard_conference + , case + when json_extract_path_text( + form_data, 'howHeard' + ) like '%Other:%' then 1 + else 0 + end as how_heard_other from pd_applications \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications_status_logs.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications_status_logs.sql new file mode 100644 index 00000000..b3c03216 --- /dev/null +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications_status_logs.sql @@ -0,0 +1,9 @@ +with + +pd_applications_status_logs as ( + select * + from {{ ref('base_dashboard_pii__pd_applications_status_logs') }} +) + +select * +from pd_applications_status_logs \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_attendances.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_attendances.sql index bdbddf80..f5f4f968 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_attendances.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_attendances.sql @@ -2,7 +2,15 @@ with pd_attendances as ( select * from {{ ref('base_dashboard_pii__pd_attendances') }} +), + +school_years as ( + select * + from {{ ref('int_school_years') }} ) -select * -from pd_attendances \ No newline at end of file +select + pda.*, + sy.school_year +from pd_attendances pda +join school_years sy on pda.created_at between sy.started_at and sy.ended_at \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_enrollments.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_enrollments.sql index 171f8eb4..afca4987 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_enrollments.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_enrollments.sql @@ -4,5 +4,17 @@ pd_enrollments as ( from {{ ref('base_dashboard_pii__pd_enrollments') }} ) -select * +select + pd_enrollment_id + , pd_workshop_id + , name + , enrolled_at + , updated_at + , user_entered_school + , teacher_id + , survey_sent_dt + , completed_survey_id + , school_info_id + , application_id + from pd_enrollments \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_sessions.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_sessions.sql index c4b2fdde..4f48df05 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_sessions.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_sessions.sql @@ -2,7 +2,23 @@ with pd_sessions as ( select * from {{ ref('base_dashboard_pii__pd_sessions') }} +), + +school_years as ( + select * + from {{ ref('int_school_years') }} ) -select * -from pd_sessions \ No newline at end of file +select + pds.pd_session_id + , pds.pd_workshop_id + , sy.school_year + , extract('year' from pds.started_at) as cal_year + , pds.started_at + , pds.ended_at + , datediff(hour, pds.started_at, pds.ended_at) as num_hours + , pds.created_at + , pds.updated_at +from pd_sessions as pds +join school_years as sy + on pds.started_at between sy.started_at and sy.ended_at \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_workshops.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_workshops.sql index 620b5ef3..0f3a5c19 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_workshops.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_workshops.sql @@ -2,7 +2,60 @@ with pd_workshops as ( select * from {{ ref('base_dashboard_pii__pd_workshops') }} +), + +school_years as ( + select * + from {{ ref('int_school_years') }} ) -select * -from pd_workshops \ No newline at end of file +select + pd_workshop_id + , organizer_id + , sy.school_year + , extract('year' from pdw.started_at) as cal_year + , lower(location_name) as location_name + , lower(location_address) as location_address + , case + when course = 'CS Principles' then 'csp' + when course = 'CS Discoveries' then 'csd' + when course = 'Computer Science A' then 'csa' + when course = 'CS Fundamentals' then 'csf' + else lower(course) + end as course_name + , case + when course = 'CS Principles' then '9_12' + when course = 'CS Discoveries' then '6_8' + when course = 'Computer Science A' then '9_12' + when course = 'CS Fundamentals' then 'k_5' + else null + end as grade_band + , case + when lower(course) = 'build your own workshop' then 1 else 0 + end as is_byow + , lower(subject) as subject + , capacity + , section_id + , pdw.started_at + , pdw.ended_at + -- , case + -- when datediff(day, pdw.started_at, pdw.ended_at) > 0 + -- then datediff(day, pdw.started_at, pdw.ended_at) + -- else null + -- end as num_days + -- , case + -- when datediff(day, pdw.started_at, pdw.ended_at) = 0 + -- then datediff(hour, pdw.started_at, pdw.ended_at) + -- else datediff(day, pdw.started_at, pdw.ended_at) * 8 + -- end as num_hours + , created_at + , updated_at + , processed_at + , regional_partner_id + -- , is_on_map + -- , is_funded + -- , funding_type + , module +from pd_workshops as pdw +join school_years as sy + on pdw.started_at between sy.started_at and sy.ended_at \ No newline at end of file diff --git a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__regional_partners.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__regional_partners.sql index d3a73f54..c6c58a64 100644 --- a/dbt/models/staging/dashboard_pii/stg_dashboard_pii__regional_partners.sql +++ b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__regional_partners.sql @@ -3,5 +3,36 @@ with regional_partners as ( from {{ ref('base_dashboard_pii__regional_partners') }} ) -select * +select + regional_partner_id + , regional_partner_group + , lower(regional_partner_name) as regional_partner_name + , is_urban + , lower(street) as address + , lower(apartment_or_suite) as apt_num + , lower(city) as city + , state + , zip_code + , created_at + , updated_at + , is_active + , case + when json_extract_path_text( + properties, 'urg_guardrail_percent' + ) != '' + then json_extract_path_text( + properties, 'urg_guardrail_percent' + ) + else '50' + end as urg_guardrail_pct + , case + when json_extract_path_text( + properties, 'frl_guardrail_percent' + ) != '' + then json_extract_path_text( + properties, 'frl_guardrail_percent' + ) + else '50' + end as frl_guardrail_pct + from regional_partners \ No newline at end of file