From 0a436ff703e5037907e1ec678b94624f3059a789 Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Wed, 7 Aug 2024 23:27:56 +0000 Subject: [PATCH 1/8] saving progress --- .../intermediate/_intermediate__models.yml | 16 ++ .../int_application_status_times.sql | 35 ++++ .../_professional_development__models.yml | 1 + .../facilitator_pd_funnel_6_12.sql | 151 ++++++++++++++++++ .../dashboard_pii/_dashboard_pii__models.yml | 4 + .../dashboard_pii/_dashboard_pii__sources.yml | 1 + .../base_dashboard_pii__pd_applications.sql | 35 ++-- ...board_pii__pd_applications_status_logs.sql | 13 ++ .../base_dashboard_pii__pd_attendances.sql | 2 +- .../base_dashboard_pii__pd_enrollments.sql | 28 ++-- .../base/base_dashboard_pii__pd_sessions.sql | 2 +- .../base/base_dashboard_pii__pd_workshops.sql | 2 +- .../base_dashboard_pii__regional_partners.sql | 4 +- .../stg_dashboard_pii__pd_applications.sql | 132 ++++++++++++++- ...board_pii__pd_applications_status_logs.sql | 9 ++ .../stg_dashboard_pii__pd_enrollments.sql | 14 +- .../stg_dashboard_pii__pd_sessions.sql | 19 ++- .../stg_dashboard_pii__pd_workshops.sql | 37 ++++- .../stg_dashboard_pii__regional_partners.sql | 34 +++- 19 files changed, 495 insertions(+), 44 deletions(-) create mode 100644 dbt/models/intermediate/int_application_status_times.sql create mode 100644 dbt/models/marts/professional_development/_professional_development__models.yml create mode 100644 dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql create mode 100644 dbt/models/staging/dashboard_pii/base/base_dashboard_pii__pd_applications_status_logs.sql create mode 100644 dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_applications_status_logs.sql diff --git a/dbt/models/intermediate/_intermediate__models.yml b/dbt/models/intermediate/_intermediate__models.yml index 69f053f7..11059e9c 100644 --- a/dbt/models/intermediate/_intermediate__models.yml +++ b/dbt/models/intermediate/_intermediate__models.yml @@ -1,6 +1,22 @@ version: 2 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/intermediate/int_application_status_times.sql b/dbt/models/intermediate/int_application_status_times.sql new file mode 100644 index 00000000..ce6aea84 --- /dev/null +++ b/dbt/models/intermediate/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/models/marts/professional_development/_professional_development__models.yml b/dbt/models/marts/professional_development/_professional_development__models.yml new file mode 100644 index 00000000..22817d2a --- /dev/null +++ b/dbt/models/marts/professional_development/_professional_development__models.yml @@ -0,0 +1 @@ +version: 2 diff --git a/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql b/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql new file mode 100644 index 00000000..d117d24c --- /dev/null +++ b/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql @@ -0,0 +1,151 @@ +with + +pd_applications as ( + select * + from {{ ref('stg_dashboard_pii__pd_applications') }} +), + +pd_enrollments as ( + select * + from {{ ref('stg_dashboard_pii__pd_enrollments') }} +), + +pd_attendances as ( + select * + from {{ ref('stg_dashboard_pii__pd_attendances') }} +), + +pd_sessions as ( + select * + from {{ ref('stg_dashboard_pii__pd_sessions') }} +), + +pd_workshops as ( + select * + from {{ ref('stg_dashboard_pii__pd_workshops') }} +), + +teachers as ( + select * + from {{ ref('dim_teachers') }} +), + +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_workshop_info as ( + select pde.pd_enrollment_id + , pde.application_id + , pde.pd_workshop_id + , pde.teacher_id + , pde.enrolled_at + , pdw.school_year + , pdw.course_name + , pdw.regional_partner_id + from pd_enrollments as pde + join pd_workshops as pdw + on pde.pd_workshop_id = pdw.pd_workshop_id +), + +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_workshop_info +) + +select distinct + af.teacher_id + , pda.pd_application_id + , teachers.teacher_email + , af.course_name + , af.school_year + , coalesce (pda.submitted, 0) as submitted + , coalesce(pda.submission_status, 'did not apply through Code.org') as submission_status + , coalesce(pda.accepted,0) as accepted + , case + when e.pd_enrollment_id is not null then 1 + else 0 + end as enrolled + , case + when att.pd_attendance_id is not null then 1 + else 0 + end as attended + , pda.admin_approval_required + , pda.admin_approval_received + , pda.scholarship_frl + , pda.scholarship_urg + , pda.how_heard + , pda.how_heard_code_website + , pda.how_heard_email + , pda.how_heard_rp_website + , pda.how_heard_rp_email + , pda.how_heard_rp_event_workshop + , pda.how_heard_teacher + , pda.how_heard_administrator + , pda.how_heard_conference + , pda.how_heard_other + , pda.applied_at + , pda.accepted_at + , e.enrolled_at + , datediff(day, pda.applied_at, pda.accepted_at) as days_applied_accepted + , datediff(day, pda.applied_at, e.enrolled_at) as days_applied_enrolled + , datediff(day, pda.accepted_at, e.enrolled_at) as days_accepted_enrolled + , pda.current_status + , coalesce(e.regional_partner_id, pda.regional_partner_id) as regional_partner_id + , 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 +join teachers + on af.teacher_id = teachers.teacher_id +left join pd_applications as pda + on pda.teacher_id = af.teacher_id + and pda.course_name = af.course_name + and pda.school_year = af.school_year +left join int_application_status_times as st + on pda.pd_application_id = st.pd_application_id +left join enrollments_with_workshop_info as e + on e.teacher_id = af.teacher_id + and e.course_name = af.course_name + and e.school_year = af.school_year +left join pd_sessions as pds + on pds.pd_workshop_id = e.pd_workshop_id +left join pd_attendances as att + on att.pd_session_id = pds.pd_session_id + and att.teacher_id = e.teacher_id +left join regional_partners as rp + on rp.regional_partner_id = + coalesce( + e.regional_partner_id + , pda.regional_partner_id + ) + + + + + + + + + + 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..8de67358 100644 --- a/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml +++ b/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml @@ -13,6 +13,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__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_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__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_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..af1d25e2 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,22 @@ 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 + , 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..9d2c94e3 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,40 @@ 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 + , location_name + , 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 'other' + end as course_name + , subject + , capacity + , section_id + , pdw.started_at + , pdw.ended_at + , 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..16bbd872 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,37 @@ with regional_partners as ( from {{ ref('base_dashboard_pii__regional_partners') }} ) -select * +select + regional_partner_id + , regional_partner_group + , regional_partner_name + , is_urban + , attention + , street + , apartment_or_suite + , 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 From d56bc11bfca384fcc7b688503a01b2a8e480309e Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Thu, 8 Aug 2024 20:10:49 +0000 Subject: [PATCH 2/8] pd_funnel_6_12 --- .../_professional_development__models.yml | 6 + .../facilitator_pd_funnel_6_12.sql | 151 ---------------- .../pd_funnel_6_12.sql | 166 ++++++++++++++++++ 3 files changed, 172 insertions(+), 151 deletions(-) delete mode 100644 dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql create mode 100644 dbt/models/marts/professional_development/pd_funnel_6_12.sql diff --git a/dbt/models/marts/professional_development/_professional_development__models.yml b/dbt/models/marts/professional_development/_professional_development__models.yml index 22817d2a..9785ffa3 100644 --- a/dbt/models/marts/professional_development/_professional_development__models.yml +++ b/dbt/models/marts/professional_development/_professional_development__models.yml @@ -1 +1,7 @@ version: 2 + +models: + - name: pd_funnel_6_12 + description: | + the model represents the entire professional development funnel for the "5 day summer" workshops (csd, csp, csa). It tracks all teachers who apply, enroll, attend, and are considered trained, along with various dimensions about their application (e.g. time between applying and enrolling). + **note**: a teacher may apply through code.org, or through a regional partner's own application process. For the external applicants, they will still be counted as "enrolled" in our system but not "applied". diff --git a/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql b/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql deleted file mode 100644 index d117d24c..00000000 --- a/dbt/models/marts/professional_development/facilitator_pd_funnel_6_12.sql +++ /dev/null @@ -1,151 +0,0 @@ -with - -pd_applications as ( - select * - from {{ ref('stg_dashboard_pii__pd_applications') }} -), - -pd_enrollments as ( - select * - from {{ ref('stg_dashboard_pii__pd_enrollments') }} -), - -pd_attendances as ( - select * - from {{ ref('stg_dashboard_pii__pd_attendances') }} -), - -pd_sessions as ( - select * - from {{ ref('stg_dashboard_pii__pd_sessions') }} -), - -pd_workshops as ( - select * - from {{ ref('stg_dashboard_pii__pd_workshops') }} -), - -teachers as ( - select * - from {{ ref('dim_teachers') }} -), - -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_workshop_info as ( - select pde.pd_enrollment_id - , pde.application_id - , pde.pd_workshop_id - , pde.teacher_id - , pde.enrolled_at - , pdw.school_year - , pdw.course_name - , pdw.regional_partner_id - from pd_enrollments as pde - join pd_workshops as pdw - on pde.pd_workshop_id = pdw.pd_workshop_id -), - -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_workshop_info -) - -select distinct - af.teacher_id - , pda.pd_application_id - , teachers.teacher_email - , af.course_name - , af.school_year - , coalesce (pda.submitted, 0) as submitted - , coalesce(pda.submission_status, 'did not apply through Code.org') as submission_status - , coalesce(pda.accepted,0) as accepted - , case - when e.pd_enrollment_id is not null then 1 - else 0 - end as enrolled - , case - when att.pd_attendance_id is not null then 1 - else 0 - end as attended - , pda.admin_approval_required - , pda.admin_approval_received - , pda.scholarship_frl - , pda.scholarship_urg - , pda.how_heard - , pda.how_heard_code_website - , pda.how_heard_email - , pda.how_heard_rp_website - , pda.how_heard_rp_email - , pda.how_heard_rp_event_workshop - , pda.how_heard_teacher - , pda.how_heard_administrator - , pda.how_heard_conference - , pda.how_heard_other - , pda.applied_at - , pda.accepted_at - , e.enrolled_at - , datediff(day, pda.applied_at, pda.accepted_at) as days_applied_accepted - , datediff(day, pda.applied_at, e.enrolled_at) as days_applied_enrolled - , datediff(day, pda.accepted_at, e.enrolled_at) as days_accepted_enrolled - , pda.current_status - , coalesce(e.regional_partner_id, pda.regional_partner_id) as regional_partner_id - , 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 -join teachers - on af.teacher_id = teachers.teacher_id -left join pd_applications as pda - on pda.teacher_id = af.teacher_id - and pda.course_name = af.course_name - and pda.school_year = af.school_year -left join int_application_status_times as st - on pda.pd_application_id = st.pd_application_id -left join enrollments_with_workshop_info as e - on e.teacher_id = af.teacher_id - and e.course_name = af.course_name - and e.school_year = af.school_year -left join pd_sessions as pds - on pds.pd_workshop_id = e.pd_workshop_id -left join pd_attendances as att - on att.pd_session_id = pds.pd_session_id - and att.teacher_id = e.teacher_id -left join regional_partners as rp - on rp.regional_partner_id = - coalesce( - e.regional_partner_id - , pda.regional_partner_id - ) - - - - - - - - - - diff --git a/dbt/models/marts/professional_development/pd_funnel_6_12.sql b/dbt/models/marts/professional_development/pd_funnel_6_12.sql new file mode 100644 index 00000000..81c5775b --- /dev/null +++ b/dbt/models/marts/professional_development/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') + + + + + + + + + + + From d3b460f41b535dec03ebbc4f351b15491bdf6b26 Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Thu, 31 Oct 2024 21:02:32 +0000 Subject: [PATCH 3/8] adding K-5 PD info --- .../pd_funnel_K_5.sql | 84 +++++++++++++++++++ 1 file changed, 84 insertions(+) create mode 100644 dbt/models/marts/professional_development/pd_funnel_K_5.sql diff --git a/dbt/models/marts/professional_development/pd_funnel_K_5.sql b/dbt/models/marts/professional_development/pd_funnel_K_5.sql new file mode 100644 index 00000000..cb1e6dd8 --- /dev/null +++ b/dbt/models/marts/professional_development/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 From 5dd5e19444cb386da753cdf02676d5e67ab23694 Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Sat, 7 Dec 2024 00:09:56 +0000 Subject: [PATCH 4/8] adding rp association --- dbt/models/marts/districts/dim_districts.sql | 27 ++++++++++++++++++- .../dim_regional_partners.sql | 18 +++++++++++++ ...oard_pii__pd_regional_partner_mappings.sql | 2 +- .../stg_dashboard_pii__regional_partners.sql | 9 +++---- 4 files changed, 49 insertions(+), 7 deletions(-) create mode 100644 dbt/models/marts/professional_development/dim_regional_partners.sql diff --git a/dbt/models/marts/districts/dim_districts.sql b/dbt/models/marts/districts/dim_districts.sql index 7d806ac7..bf23c584 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') }} ), +rp_mappings as ( + select * + from {{ ref('stg_dashboard_pii__pd_regional_partner_mappings') }} +), + +regional_partners as ( + select * + from {{ ref('dim_regional_partners') }} +), + 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 rp_mappings.regional_partner_id = regional_partners.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/dim_regional_partners.sql b/dbt/models/marts/professional_development/dim_regional_partners.sql new file mode 100644 index 00000000..77483e77 --- /dev/null +++ b/dbt/models/marts/professional_development/dim_regional_partners.sql @@ -0,0 +1,18 @@ +with + +regional_partners as ( + select * + from {{ ref('stg_dashboard_pii__regional_partners') }} +) + +select + regional_partner_id + , regional_partner_name + , is_urban + , address + , apt_num + , city + , state + , zip_code + , is_active +from regional_partners 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/stg_dashboard_pii__regional_partners.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__regional_partners.sql index 16bbd872..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 @@ -6,12 +6,11 @@ with regional_partners as ( select regional_partner_id , regional_partner_group - , regional_partner_name + , lower(regional_partner_name) as regional_partner_name , is_urban - , attention - , street - , apartment_or_suite - , city + , lower(street) as address + , lower(apartment_or_suite) as apt_num + , lower(city) as city , state , zip_code , created_at From ee3e5a40db0e869e93a47d2f30db27242f7b219b Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Mon, 16 Dec 2024 17:05:58 +0000 Subject: [PATCH 5/8] some changes --- dbt/data/seed_pl_grade_band_mappings.csv | 31 ++++++ dbt/models/marts/districts/dim_districts.sql | 10 +- .../dim_global_teacher_roster.sql | 0 ...global_trained_teacher_script_progress.sql | 0 .../dim_pl_activity.sql | 104 ++++++++++++++++++ .../dim_regional_partners.sql | 24 ++-- .../dim_self_paced_pd_activity.sql | 0 ...ernal_datasets__pl_grade_band_mappings.sql | 11 ++ 8 files changed, 165 insertions(+), 15 deletions(-) create mode 100644 dbt/data/seed_pl_grade_band_mappings.csv rename dbt/models/marts/{teachers => professional_development}/dim_global_teacher_roster.sql (100%) rename dbt/models/marts/{teachers => professional_development}/dim_global_trained_teacher_script_progress.sql (100%) create mode 100644 dbt/models/marts/professional_development/dim_pl_activity.sql rename dbt/models/marts/{teachers => professional_development}/dim_self_paced_pd_activity.sql (100%) create mode 100644 dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql diff --git a/dbt/data/seed_pl_grade_band_mappings.csv b/dbt/data/seed_pl_grade_band_mappings.csv new file mode 100644 index 00000000..19207f2d --- /dev/null +++ b/dbt/data/seed_pl_grade_band_mappings.csv @@ -0,0 +1,31 @@ +topic,grade_band +Teaching How AI Makes Decisions,K-5 +Teaching Elementary Game Design,K-5 +Teaching micro:bit Maker Module,K-5 +Computer Science Basics for K-5 Teachers,Skills-focused +Teaching CS Fundamentals,K-5 +Teaching CS Connections,K-5 +Teaching Exploring Generative AI,9-12 +Teaching Coding with AI,9-12 +Teaching Interactive Animations and Games,6-8 +Teaching Computer Science Discoveries,6-8 +Teaching Problem Solving and Computing,6-8 +Teaching AI and Machine Learning,6-8 +Teaching Data and Society,6-8 +Teaching the Design Process,6-8 +Teaching Web Development,6-8 +AI 101 ,Skills-focused +Teaching Computer Vision,9-12 +Teaching Computer Science Principles,9-12 +Getting Started wtih Code.org Self-Paced PL,Skills-focused +Equity Self-Paced PL,Skills-focused +Debugging Self-Paced PL,Skills-focused +Foundations of CS PL,9-12 +Data Science PL,9-12 +Computer Systems & Devices PL,9-12 +Intro to Programming/Python PL,9-12 +Networks and the Internet PL,9-12 +Cybersecurity PL,9-12 +Creativity with AI PL,9-12 +K-5 Music Lab PL,K-5 +CSD Music Lab PL,6-8 \ No newline at end of file diff --git a/dbt/models/marts/districts/dim_districts.sql b/dbt/models/marts/districts/dim_districts.sql index bf23c584..1b0f4077 100644 --- a/dbt/models/marts/districts/dim_districts.sql +++ b/dbt/models/marts/districts/dim_districts.sql @@ -12,14 +12,14 @@ school_districts as ( from {{ ref('stg_dashboard__school_districts') }} ), -rp_mappings as ( +regional_partners as ( select * - from {{ ref('stg_dashboard_pii__pd_regional_partner_mappings') }} + from {{ ref('dim_regional_partners') }} ), -regional_partners as ( +rp_mappings as ( select * - from {{ ref('dim_regional_partners') }} + from {{ ref('stg_dashboard_pii__pd_regional_partner_mappings') }} ), combined as ( @@ -68,7 +68,7 @@ combined as ( ) ) left join regional_partners - on rp_mappings.regional_partner_id = regional_partners.regional_partner_id + on regional_partners.regional_partner_id = rp_mappings.regional_partner_id where dim_schools.school_district_id is not null {{ dbt_utils.group_by(8) }} ) 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..a7310390 --- /dev/null +++ b/dbt/models/marts/professional_development/dim_pl_activity.sql @@ -0,0 +1,104 @@ +with + +self_paced_activity as ( + select + teacher_id + , level_created_school_year as school_year + , case + when course_name like '%csd%' then 'csd' + when course_name like '%csf%' then 'csf' + when course_name like '%csp%' then 'csp' + when course_name like '%csa%' then 'csa' + when course_name like '%csc%' then 'csc' + end as course_name + , 'self_paced' as activity_type + , content_area + , 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') }} + group by 1,2,3,4,5 +), + +teacher_schools_historical as ( + select * + from {{ ref('int_teacher_schools_historical') }} +), + +schools as ( + select * + from {{ ref('dim_schools') }} +), + +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') }} +), + +regional_partners as ( + select * + from {{ ref('dim_regional_partners') }} +), + +pl_grade_band_mappings as ( + select * + from {{ ref('stg_external_datasets__pl_grade_band_mappings') }} +), + +workshop_activity as ( + select + +) + +select + spa.teacher_id + , spa.school_year + , spa.course_name as topic_area + , spa.activity_type + , spa.first_activity_at + , spa.last_activity_at + , spa.num_levels + , spa.content_area + , tsh.school_id + , schools.school_district_id + +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 \ No newline at end of file diff --git a/dbt/models/marts/professional_development/dim_regional_partners.sql b/dbt/models/marts/professional_development/dim_regional_partners.sql index 77483e77..5f94b99e 100644 --- a/dbt/models/marts/professional_development/dim_regional_partners.sql +++ b/dbt/models/marts/professional_development/dim_regional_partners.sql @@ -3,16 +3,20 @@ 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_partner_id - , regional_partner_name - , is_urban - , address - , apt_num - , city - , state - , zip_code - , is_active -from regional_partners + 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 100% 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 diff --git a/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql b/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql new file mode 100644 index 00000000..ecc33138 --- /dev/null +++ b/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql @@ -0,0 +1,11 @@ +with + +mappings as ( + select * + from {{ ref('seed_pl_grade_band_mappings') }} +) + +select + lower(topic) as topic + , lower(grade_band) as grade_band +from mappings \ No newline at end of file From 82203eaff6fcb84f73c6ed4f6470e9227756e34e Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Fri, 20 Dec 2024 00:39:48 +0000 Subject: [PATCH 6/8] finishing model 1 --- dbt/data/seed_pl_grade_band_mappings.csv | 1 + .../dim_pl_activity.sql | 161 ++++++++++++++---- .../dim_self_paced_pd_activity.sql | 1 + .../staging/dashboard/_dashboard__sources.yml | 1 + .../base/base_dashboard__course_offerings.sql | 29 ++++ .../stg_dashboard__course_offerings.sql | 36 ++++ .../dashboard_pii/_dashboard_pii__sources.yml | 1 + ...ard_pii__course_offerings_pd_workshops.sql | 12 ++ ...ard_pii__course_offerings_pd_workshops.sql | 13 ++ .../stg_dashboard_pii__pd_attendances.sql | 12 +- .../stg_dashboard_pii__pd_sessions.sql | 1 + .../stg_dashboard_pii__pd_workshops.sql | 35 +++- ...ernal_datasets__pl_grade_band_mappings.sql | 8 +- 13 files changed, 264 insertions(+), 47 deletions(-) create mode 100644 dbt/models/staging/dashboard/base/base_dashboard__course_offerings.sql create mode 100644 dbt/models/staging/dashboard/stg_dashboard__course_offerings.sql create mode 100644 dbt/models/staging/dashboard_pii/base/base_dashboard_pii__course_offerings_pd_workshops.sql create mode 100644 dbt/models/staging/dashboard_pii/stg_dashboard_pii__course_offerings_pd_workshops.sql diff --git a/dbt/data/seed_pl_grade_band_mappings.csv b/dbt/data/seed_pl_grade_band_mappings.csv index 19207f2d..4c6031f3 100644 --- a/dbt/data/seed_pl_grade_band_mappings.csv +++ b/dbt/data/seed_pl_grade_band_mappings.csv @@ -9,6 +9,7 @@ Teaching Exploring Generative AI,9-12 Teaching Coding with AI,9-12 Teaching Interactive Animations and Games,6-8 Teaching Computer Science Discoveries,6-8 +Teaching CS Discoveries,6-8 Teaching Problem Solving and Computing,6-8 Teaching AI and Machine Learning,6-8 Teaching Data and Society,6-8 diff --git a/dbt/models/marts/professional_development/dim_pl_activity.sql b/dbt/models/marts/professional_development/dim_pl_activity.sql index a7310390..9f2e07e5 100644 --- a/dbt/models/marts/professional_development/dim_pl_activity.sql +++ b/dbt/models/marts/professional_development/dim_pl_activity.sql @@ -2,22 +2,22 @@ with self_paced_activity as ( select - teacher_id - , level_created_school_year as school_year - , case - when course_name like '%csd%' then 'csd' - when course_name like '%csf%' then 'csf' - when course_name like '%csp%' then 'csp' - when course_name like '%csa%' then 'csa' - when course_name like '%csc%' then 'csc' - end as course_name - , 'self_paced' as activity_type - , content_area - , min(level_created_dt) as first_activity_at - , max(level_created_dt) as last_activity_at - , count(distinct level_script_id) as num_levels + 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 null + 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') }} - group by 1,2,3,4,5 + {{ dbt_utils.group_by(5) }} ), teacher_schools_historical as ( @@ -30,6 +30,11 @@ schools as ( from {{ ref('dim_schools') }} ), +districts as ( + select * + from {{ ref('dim_districts') }} +), + pd_enrollments as ( select pd_enrollment_id @@ -45,6 +50,7 @@ pd_attendances as ( pd_attendance_id , pd_session_id , teacher_id + , school_year from {{ ref('stg_dashboard_pii__pd_attendances') }} ), @@ -53,7 +59,7 @@ pd_sessions as ( pd_session_id , pd_workshop_id , school_year - , cal_year + , num_hours from {{ ref('stg_dashboard_pii__pd_sessions') }} ), @@ -62,13 +68,31 @@ pd_workshops as ( pd_workshop_id , organizer_id , school_year - , cal_year , course_name + , case + when course_name = 'csf' then 'k_5' + when course_name = 'csc' then 'k_5' + when course_name = 'csd' then '6_8' + when course_name = 'csp' then '9_12' + when course_name = 'csa' then '9_12' + else null + end as grade_band , 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') }} +), + regional_partners as ( select * from {{ ref('dim_regional_partners') }} @@ -79,26 +103,89 @@ pl_grade_band_mappings as ( from {{ ref('stg_external_datasets__pl_grade_band_mappings') }} ), -workshop_activity as ( - select - -) +facilitated_pd as ( + select distinct + pda.teacher_id, + pdw.school_year, + 'facilitated' as pd_type, + pdw.pd_workshop_id, + pdw.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(mappings.grade_band, pdw.grade_band) as grade_band, + tsh.school_id, + schools.school_district_id, + -- pdw.subject, + -- co.display_name + --co.cs_topic, + cast(null as bigint) as num_levels, + sum(pds.num_hours) as num_hours -select - spa.teacher_id - , spa.school_year - , spa.course_name as topic_area - , spa.activity_type - , spa.first_activity_at - , spa.last_activity_at - , spa.num_levels - , spa.content_area - , tsh.school_id - , schools.school_district_id - -from self_paced_activity spa +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_offerings_pd_workshops copw + on pdw.pd_workshop_id = copw.pd_workshop_id +left join course_offerings co + on copw.course_offering_id = co.course_offering_id +left join pl_grade_band_mappings mappings + on co.display_name = mappings.topic left join teacher_schools_historical tsh - on spa.teacher_id = tsh.teacher_id - and spa.school_year = tsh.started_at_sy + 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 \ No newline at end of file + 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, + cast(null as bigint) as pd_workshop_id, + cast(null as bigint) as 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.first_activity_at + -- , spa.last_activity_at + 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_self_paced_pd_activity.sql b/dbt/models/marts/professional_development/dim_self_paced_pd_activity.sql index 2f6b4c84..1f8294aa 100644 --- a/dbt/models/marts/professional_development/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 dbd396cf..20f484d0 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..e682232e --- /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__sources.yml b/dbt/models/staging/dashboard_pii/_dashboard_pii__sources.yml index 8de67358..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 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/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_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_sessions.sql b/dbt/models/staging/dashboard_pii/stg_dashboard_pii__pd_sessions.sql index af1d25e2..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 @@ -16,6 +16,7 @@ select , 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 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 9d2c94e3..c717fe33 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 @@ -14,27 +14,48 @@ select , organizer_id , sy.school_year , extract('year' from pdw.started_at) as cal_year - , location_name - , location_address + , 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 'other' + else lower(course) end as course_name - , subject + , 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' + when course = 'Foundations of CS' then '9_12' + 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 + -- , is_on_map + -- , is_funded + -- , funding_type , module from pd_workshops as pdw join school_years as sy diff --git a/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql b/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql index ecc33138..4008d2b5 100644 --- a/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql +++ b/dbt/models/staging/external_datasets/stg_external_datasets__pl_grade_band_mappings.sql @@ -7,5 +7,11 @@ mappings as ( select lower(topic) as topic - , lower(grade_band) as grade_band + , case + when lower(grade_band) = 'k-5' then 'k_5' + when lower(grade_band) = '6-8' then '6_8' + when lower(grade_band) = '9-12' then '9_12' + when lower(grade_band) = 'skills-focused' then 'skills_focused' + else lower(grade_band) + end as grade_band from mappings \ No newline at end of file From 1917d60702877528bd0ee3110e39e2dd4fac17cc Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Fri, 20 Dec 2024 00:44:44 +0000 Subject: [PATCH 7/8] small changes --- .../marts/professional_development/dim_pl_activity.sql | 9 +-------- .../dashboard_pii/stg_dashboard_pii__pd_workshops.sql | 1 - 2 files changed, 1 insertion(+), 9 deletions(-) diff --git a/dbt/models/marts/professional_development/dim_pl_activity.sql b/dbt/models/marts/professional_development/dim_pl_activity.sql index 9f2e07e5..f504f7ca 100644 --- a/dbt/models/marts/professional_development/dim_pl_activity.sql +++ b/dbt/models/marts/professional_development/dim_pl_activity.sql @@ -69,14 +69,7 @@ pd_workshops as ( , organizer_id , school_year , course_name - , case - when course_name = 'csf' then 'k_5' - when course_name = 'csc' then 'k_5' - when course_name = 'csd' then '6_8' - when course_name = 'csp' then '9_12' - when course_name = 'csa' then '9_12' - else null - end as grade_band + , grade_band , subject , regional_partner_id , is_byow 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 c717fe33..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 @@ -28,7 +28,6 @@ select when course = 'CS Discoveries' then '6_8' when course = 'Computer Science A' then '9_12' when course = 'CS Fundamentals' then 'k_5' - when course = 'Foundations of CS' then '9_12' else null end as grade_band , case From 893fb477785183e1a916547929a79c7c8e532597 Mon Sep 17 00:00:00 2001 From: "allison@code.org" Date: Fri, 20 Dec 2024 22:22:39 +0000 Subject: [PATCH 8/8] saving progress --- .../dim_pl_engagement.sql | 75 +++++++++++++++++++ 1 file changed, 75 insertions(+) create mode 100644 dbt/models/marts/professional_development/dim_pl_engagement.sql 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..cfda3a93 --- /dev/null +++ b/dbt/models/marts/professional_development/dim_pl_engagement.sql @@ -0,0 +1,75 @@ +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(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 +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_1.teacher_id + and pl.school_year_int + 1 = act_1.school_year_int + + + + + +