Skip to content
New issue

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

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

Already on GitHub? Sign in to your account

Feature/pd_funnel_6_12 #147

Merged
merged 44 commits into from
Jan 18, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
44 commits
Select commit Hold shift + click to select a range
0a436ff
saving progress
allison-code-dot-org Aug 7, 2024
d56bc11
pd_funnel_6_12
allison-code-dot-org Aug 8, 2024
a99d178
rebasing
allison-code-dot-org Aug 13, 2024
60c5ce6
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Aug 22, 2024
0fd7dba
Merge branch 'main' into feature/pd
jordan-springer Sep 2, 2024
6c51449
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Sep 17, 2024
fe2866f
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Sep 19, 2024
746840b
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Oct 31, 2024
d3b460f
adding K-5 PD info
allison-code-dot-org Oct 31, 2024
233a7fa
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Oct 31, 2024
b483dee
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Dec 2, 2024
6eeea34
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Dec 6, 2024
5dd5e19
adding rp association
allison-code-dot-org Dec 7, 2024
ee3e5a4
some changes
allison-code-dot-org Dec 16, 2024
aa13251
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Dec 16, 2024
45d5ed7
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Dec 19, 2024
82203ea
finishing model 1
allison-code-dot-org Dec 20, 2024
1917d60
small changes
allison-code-dot-org Dec 20, 2024
642df40
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Dec 20, 2024
893fb47
saving progress
allison-code-dot-org Dec 20, 2024
6da44cf
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Jan 6, 2025
fd14333
small changes
allison-code-dot-org Jan 7, 2025
f555ce3
saving changes
allison-code-dot-org Jan 8, 2025
cb240dc
added documentation
allison-code-dot-org Jan 8, 2025
fa46e5a
deleting files
allison-code-dot-org Jan 8, 2025
1947831
archiving
allison-code-dot-org Jan 8, 2025
dd73b1d
small change
allison-code-dot-org Jan 8, 2025
f4ecd92
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
allison-code-dot-org Jan 8, 2025
d418b04
Merge branch 'main' into feature/pd
allison-code-dot-org Jan 9, 2025
1024527
Merge branch 'main' of https://github.com/code-dot-org/analytics into…
nataliazm99 Jan 14, 2025
d4f6585
Update dbt/models/marts/professional_development/_professional_develo…
allison-code-dot-org Jan 16, 2025
75d210d
fixing num_hours issue
allison-code-dot-org Jan 17, 2025
672a884
Merge branch 'feature/pd' of https://github.com/code-dot-org/analytic…
allison-code-dot-org Jan 17, 2025
0281b07
small changes
allison-code-dot-org Jan 17, 2025
b5a6ee2
Update dbt/models/marts/professional_development/dim_pl_engagement.sql
allison-code-dot-org Jan 17, 2025
5f8aaeb
Update dbt/models/marts/professional_development/dim_pl_engagement.sql
allison-code-dot-org Jan 17, 2025
0e283a8
adding us_intl
allison-code-dot-org Jan 17, 2025
a09ce08
changing course_name_implementation logic
allison-code-dot-org Jan 17, 2025
142f65e
removing school_year_int from model
allison-code-dot-org Jan 17, 2025
bbac283
little fix
allison-code-dot-org Jan 17, 2025
af05972
small change
allison-code-dot-org Jan 17, 2025
9dd521d
small change
allison-code-dot-org Jan 17, 2025
30023a8
small change
allison-code-dot-org Jan 17, 2025
7b3932d
Merge branch 'main' into feature/pd
allison-code-dot-org Jan 17, 2025
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
35 changes: 35 additions & 0 deletions dbt/archive/int_application_status_times.sql
Original file line number Diff line number Diff line change
@@ -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
)
)
166 changes: 166 additions & 0 deletions dbt/archive/pd_funnel_6_12.sql
Original file line number Diff line number Diff line change
@@ -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')











84 changes: 84 additions & 0 deletions dbt/archive/pd_funnel_K_5.sql
Original file line number Diff line number Diff line change
@@ -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')
18 changes: 17 additions & 1 deletion dbt/models/intermediate/_intermediate__models.yml
Original file line number Diff line number Diff line change
@@ -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:
Expand Down
27 changes: 26 additions & 1 deletion dbt/models/marts/districts/dim_districts.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand All @@ -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,
Expand All @@ -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 *
Expand Down
Loading