Skip to content
New issue

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

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

Already on GitHub? # to your account

Quick psat table swap for grad requirements #2470

Open
wants to merge 31 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
31 commits
Select commit Hold shift + click to select a range
6736b43
added comment/reminder to carat current year view
GabyRangelB Feb 20, 2025
293ff10
brought over academic year to int_assessments_college_assessment from…
GabyRangelB Feb 20, 2025
d423d58
added academic year to join because the dash currently supports only …
GabyRangelB Feb 20, 2025
b32bcfc
deprecating instances of illum tables for psat and replacing them wit…
GabyRangelB Feb 20, 2025
6dfbd1d
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 20, 2025
6071e0b
changed test_type to scope
GabyRangelB Feb 20, 2025
ebbf5bf
updated grad paths
GabyRangelB Feb 20, 2025
9290307
trunk
GabyRangelB Feb 20, 2025
ce6e50e
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 20, 2025
6cc492b
fixed rpt_college_assessment.... will do qa tomorrow
GabyRangelB Feb 20, 2025
81fc095
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 21, 2025
1182607
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 21, 2025
8508c30
fixed course_discipline conversion
GabyRangelB Feb 21, 2025
91934c9
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 21, 2025
1d21e7b
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 21, 2025
340e338
added fake scope so that the PSAT requirement doesnt distinguish betw…
GabyRangelB Feb 21, 2025
801dcbf
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 25, 2025
04a5a4f
cleaned up score_type for psat
GabyRangelB Feb 25, 2025
580ebb5
new njgpa xfer scores view
GabyRangelB Feb 25, 2025
762c9e6
thinking about new path calcs
GabyRangelB Feb 26, 2025
dfb54ad
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 26, 2025
db39f1c
added rn_undergrad to filter
GabyRangelB Feb 26, 2025
1809206
njgpa scores
GabyRangelB Feb 26, 2025
dbe32d0
act,sat,psat and rn highest
GabyRangelB Feb 26, 2025
c296661
hid state_studentnumber_int
GabyRangelB Feb 26, 2025
369017e
fixed discipline joins
GabyRangelB Feb 26, 2025
7af9e26
added cutoff table
GabyRangelB Feb 26, 2025
edb90d6
rebuilt cutoffs to catch changes
GabyRangelB Feb 26, 2025
1d3e794
fixed psat union
GabyRangelB Feb 26, 2025
2e819b5
need to bring new scores
GabyRangelB Feb 26, 2025
179e26b
Merge branch 'main' of https://github.com/TEAMSchools/teamster into q…
GabyRangelB Feb 27, 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
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
select
powerschool_student_number as student_number,
administration_round,
academic_year,
latest_psat_date as test_date,
test_type as scope,
test_subject as subject_area,
Expand All @@ -19,6 +20,7 @@ select
null as student_number,

administration_round,
academic_year,
`date` as test_date,
test_type as scope,
subject_area,
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,247 @@
-- purpose of this view: some version of the nonsense below is repeated via CTEs in
-- two views: the old version of this view (int_students__graduation_path_codes.sql) and
-- rpt_tableau__graduation_requirements.sql. path_codes then feeds autocomm_students
-- to send to PS the final graduation eligibility code. currently, the CTE versions
-- require manual adjustments of the ACT SAT PSAT et al thresholds needed to
-- calculate eligibility for graduation under these pathways IF a student tests for
-- NJGPA. i can share a doc of the logic behind the checks, if that helps. the point
-- is that these grad requirements can change even after a student has already been
-- assigned a path, so we need to be able to check grad pathways at the academic year
-- level (i.e. a student who is supposed to graduate this year may have different
-- ACT/SAT/PSAT thredsholds than a student who is supposed to graduate next year). i
-- started building a lookup table that allows me to customize the thresholds by
-- cohort/test/score_type (subject). it currently lives on the same table where walters
-- has the promo status cutoffs (stg_reporting__promo_status_cutoffs). im not married
-- to this location, so if you think it goes better somewhere else, please move it.
-- this view will also help us track the distribution of grad pathways over time to
-- share with katie and co which pathways our students take the most, which can
-- influence strategy decisions around which college readiness assessments serve our
-- students best. thank you for coming to my tedtalk
with
students as (
select
e._dbt_source_relation,
e.students_dcid,
e.studentid,
e.student_number,
e.state_studentnumber,
e.salesforce_id,
e.grade_level,
e.cohort,
e.has_fafsa,
e.discipline,
e.powerschool_credittype,

-- this is not their final code, but it is used to calculate their final
-- code
u.values_column as ps_grad_path_code,

safe_cast(e.state_studentnumber as numeric) as state_studentnumber_int,

-- this is the date we start holding 11th graders accountable to
-- fulfilling the NJGPA test requirement
date({{ var("current_academic_year") + 1 }}, 05, 31) as njgpa_date_11th,

-- this is the date we start holding 12th graders accountable to
-- fulfilling the FAFSA requirement
if(
current_date('{{ var("local_timezone") }}')
< date({{ var("current_academic_year") + 1 }}, 01, 01),
true,
false
) as is_before_fafsa_12th,

from {{ ref("int_extracts__student_enrollments_subjects") }} as e
left join
{{ ref("int_powerschool__s_nj_stu_x_unpivot") }} as u
on e.students_dcid = u.studentsdcid
and e.discipline = u.discipline
and {{ union_dataset_join_clause(left_alias="e", right_alias="u") }}
and u.value_type = 'Graduation Pathway'
where e.region != 'Miami' and grade_level >= 8 and rn_undergrad = 1
),

scores as (
-- njgpa transfer scores
select
s.student_number,
s.state_studentnumber,
s.salesforce_id,
x.testscalescore as scale_score,
x.testcode as score_type,
x.test_name as pathway_option,

x.discipline,

from students as s
inner join
{{ ref("int_powerschool__state_assessments_transfer_scores") }} as x
on s.state_studentnumber = x.state_studentnumber
and s.discipline = x.discipline

union all

-- njgpa scores from file
select
s.student_number,
s.state_studentnumber,
s.salesforce_id,
n.testscalescore as scale_score,
n.testcode as score_type,
n.assessment_name as pathway_option,

n.discipline,

from students as s
inner join
{{ ref("stg_pearson__njgpa") }} as n
on s.state_studentnumber_int = n.statestudentidentifier
and s.discipline = n.discipline
where n.testscorecomplete = 1 and n.testcode in ('ELAGP', 'MATGP')

union all

-- act/sat scores
select
s.student_number,
s.state_studentnumber,
s.salesforce_id,
a.scale_score,
a.score_type,
a.scope as pathway_option,

if(a.course_discipline = 'ENG', 'ELA', 'Math') as discipline,

from students as s
inner join
{{ ref("int_assessments__college_assessment") }} as a
on s.salesforce_id = a.salesforce_id
and s.powerschool_credittype = a.course_discipline
and a.scope in ('ACT', 'SAT')
and a.course_discipline in ('MATH', 'ENG')

union all

-- psat scores
select
s.student_number,
s.state_studentnumber,
s.salesforce_id,
p.scale_score,
p.score_type,
p.scope as pathway_option,

if(p.course_discipline = 'ENG', 'ELA', 'Math') as discipline,

from students as s
inner join
{{ ref("int_assessments__college_assessment") }} as p
on s.student_number = p.student_number
and s.powerschool_credittype = p.course_discipline
and p.scope in ('PSAT10', 'PSAT NMSQT')
and p.course_discipline in ('MATH', 'ENG')
),

lookup_table as (
select
s.* except (state_studentnumber_int),

p.pathway_option,
p.score_type,
p.scale_score,

c.code as pathway_code,
c.cutoff,

if(p.scale_score >= c.cutoff, true, false) as met_pathway_cutoff,

row_number() over (
partition by s.student_number, p.score_type order by p.scale_score desc
) as rn_highest,

from students as s
left join
scores as p
on s.student_number = p.student_number
and s.discipline = p.discipline
inner join
{{ ref("stg_reporting__promo_status_cutoffs") }} as c
on p.discipline = c.discipline
and p.pathway_option = c.type
and p.score_type = c.subject
and s.cohort = c.cohort
and c.`domain` = 'Graduation Pathways'
),

-- having to collapse the unpivot
unpivot_calcs as (
select
_dbt_source_relation,
student_number,
salesforce_id,
state_studentnumber,
grade_level,
cohort,
has_fafsa,
discipline,
powerschool_credittype,
ps_grad_path_code,
njgpa_date_11th,
is_before_fafsa_12th,

if(max(met_njgpa) is not null, true, false) as njgpa_attempt,

coalesce(max(met_njgpa), false) as met_njgpa,
coalesce(max(met_act), false) as met_act,
coalesce(max(met_sat), false) as met_sat,
coalesce(max(met_psat10), false) as met_psat10,
coalesce(max(met_psat_nmsqt), false) as met_psat_nmsqt,

from
lookup_table pivot (
max(met_pathway_cutoff)
for pathway_option in (
'NJGPA' as met_njgpa,
'ACT' as met_act,
'SAT' as met_sat,
'PSAT10' as met_psat10,
'PSAT NMSQT' as met_psat_nmsqt
)
)
where rn_highest = 1
group by all
)

select
*,

case
when grade_level != 12
then ps_grad_path_code
when ps_grad_path_code in ('M', 'N', 'O', 'P')
then ps_grad_path_code
when met_njgpa
then 'S'
when njgpa_attempt and not met_njgpa and met_act
then 'E'
when njgpa_attempt and not met_njgpa and not met_act and met_sat
then 'D'
when
njgpa_attempt
and not met_njgpa
and not met_act
and not met_sat
and met_psat10
then 'J'
when
njgpa_attempt
and not met_njgpa
and not met_act
and not met_sat
and not met_psat10
and met_psat_nmsqt
then 'K'
else 'R'
end as final_grad_path,

from unpivot_calcs
Original file line number Diff line number Diff line change
Expand Up @@ -9,8 +9,12 @@ with
score,
test_type,

concat(
test_name, '_', regexp_extract(score_type, r'^[^_]+_(.+)')
-- reason for proposed change: this concat creates names like
-- psat10_psat_math_section. it seems a bit redundant.
regexp_replace(
concat(test_name, '_', regexp_extract(score_type, r'^[^_]+_(.+)')),
'_psat_',
'_'
) as score_type,

case
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -145,6 +145,7 @@ left join
and e.expected_test_type = o.test_type
and e.expected_scope = o.scope
and e.expected_subject_area = o.subject_area
and e.academic_year = o.academic_year
left join
course_subjects_roster as c
on e.student_number = c.student_number
Expand Down Expand Up @@ -217,6 +218,7 @@ left join
and e.expected_test_type = o.test_type
and e.expected_scope = o.scope
and e.expected_subject_area = o.subject_area
and e.academic_year = o.academic_year
left join
course_subjects_roster as c
on e.student_number = c.student_number
Expand All @@ -225,6 +227,8 @@ left join
where
e.expected_test_type = 'Official' and e.expected_scope in ('PSAT NMSQT', 'PSAT 8/9')

-- this code is a placeholder for now, as we are not reporting practice scores for
-- sy2425, but will do so again for sy2526
union all

select
Expand Down
Loading