diff --git a/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__college_assessment.sql b/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__college_assessment.sql index 9714cf889a..84bde48013 100644 --- a/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__college_assessment.sql +++ b/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__college_assessment.sql @@ -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, @@ -19,6 +20,7 @@ select null as student_number, administration_round, + academic_year, `date` as test_date, test_type as scope, subject_area, diff --git a/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__graduation_eligibility_paths.sql b/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__graduation_eligibility_paths.sql new file mode 100644 index 0000000000..b59d7fb67a --- /dev/null +++ b/src/dbt/kipptaf/models/assessments/intermediate/int_assessments__graduation_eligibility_paths.sql @@ -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 diff --git a/src/dbt/kipptaf/models/collegeboard/intermediate/int_collegeboard__psat_unpivot.sql b/src/dbt/kipptaf/models/collegeboard/intermediate/int_collegeboard__psat_unpivot.sql index d2c90e0195..4879a56e35 100644 --- a/src/dbt/kipptaf/models/collegeboard/intermediate/int_collegeboard__psat_unpivot.sql +++ b/src/dbt/kipptaf/models/collegeboard/intermediate/int_collegeboard__psat_unpivot.sql @@ -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 diff --git a/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__college_assessment_dashboard.sql b/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__college_assessment_dashboard.sql index bb542a94a8..7cf4fc7a06 100644 --- a/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__college_assessment_dashboard.sql +++ b/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__college_assessment_dashboard.sql @@ -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 @@ -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 @@ -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 diff --git a/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__graduation_requirements.sql b/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__graduation_requirements.sql index 2b825b26e1..e709e68433 100644 --- a/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__graduation_requirements.sql +++ b/src/dbt/kipptaf/models/extracts/tableau/rpt_tableau__graduation_requirements.sql @@ -55,47 +55,6 @@ with ) ), - transfer_scores as ( - select - b._dbt_source_relation, - b.name as test_name, - - s.studentid, - s.grade_level as assessment_grade_level, - - t.numscore as testscalescore, - t.alphascore as testperformancelevel, - - r.name as testcode, - - case - r.name when 'ELAGP' then 'ELA' when 'MATGP' then 'Math' - end as discipline, - case - r.name - when 'ELAGP' - then 'English Language Arts' - when 'MATGP' - then 'Mathematics' - end as `subject`, - from {{ ref("stg_powerschool__test") }} as b - left join - {{ ref("stg_powerschool__studenttest") }} as s - on b.id = s.testid - and {{ union_dataset_join_clause(left_alias="b", right_alias="s") }} - left join - {{ ref("stg_powerschool__studenttestscore") }} as t - on s.studentid = t.studentid - and s.id = t.studenttestid - and {{ union_dataset_join_clause(left_alias="s", right_alias="t") }} - left join - {{ ref("stg_powerschool__testscore") }} as r - on s.testid = r.testid - and t.testscoreid = r.id - and {{ union_dataset_join_clause(left_alias="s", right_alias="r") }} - where b.name = 'NJGPA' - ), - transfer_roster as ( select e.student_number as localstudentidentifier, @@ -108,7 +67,7 @@ with safe_cast(e.state_studentnumber as int) as statestudentidentifier, from roster as e left join - transfer_scores as x + {{ ref("int_powerschool__state_assessments_transfer_scores") }} as x on e.studentid = x.studentid and {{ union_dataset_join_clause(left_alias="e", right_alias="x") }} where x.studentid is not null @@ -125,19 +84,21 @@ with case when testcode = 'ELAGP' then 'ELA' when testcode = 'MATGP' then 'Math' end as discipline, + from {{ ref("stg_pearson__njgpa") }} where testscorecomplete = 1 and testcode in ('ELAGP', 'MATGP') union all select - localstudentidentifier, - statestudentidentifier, + student_number as localstudentidentifier, + cast(state_studentnumber as numeric) as statestudentidentifier, `subject`, testcode, testscalescore, discipline, - from transfer_roster + + from {{ ref("int_powerschool__state_assessments_transfer_scores") }} ), njgpa_rollup as ( @@ -160,102 +121,47 @@ with act_sat_psat_official as ( select - contact, + salesforce_id, + student_number, test_type, - score, - - case - when score_type in ('act_reading', 'sat_reading_test_score', 'sat_ebrw') - then 'ELA' - when score_type in ('act_math', 'sat_math_test_score', 'sat_math') - then 'Math' - end as discipline, + scale_score, + subject_area, case - when score_type in ('act_reading', 'sat_reading_test_score') - then 'Reading' - when score_type in ('act_math', 'sat_math') - then 'Math' - when score_type = 'sat_math_test_score' - then 'Math Test' - when score_type = 'sat_ebrw' - then 'EBRW' - end as `subject`, - - case - when score_type in ('act_reading', 'act_math') and score >= 17 + when score_type in ('act_reading', 'act_math') and scale_score >= 17 + then true + when score_type = 'sat_reading_test_score' and scale_score >= 23 then true - when score_type = 'sat_reading_test_score' and score >= 23 + when score_type = 'sat_math_test_score' and scale_score >= 22 then true - when score_type = 'sat_math_test_score' and score >= 22 + when score_type = 'sat_math' and scale_score >= 440 then true - when score_type = 'sat_math' and score >= 440 + when score_type = 'sat_ebrw' and scale_score >= 450 then true - when score_type = 'sat_ebrw' and score >= 450 + when + score_type in ( + 'psat10_psat_math_section', + 'psatnmsqt_psat_math_section', + 'psat10_psat_ebrw', + 'psatnmsqt_psat_ebrw' + ) + and scale_score >= 420 then true else false end as met_pathway_requirement, - from {{ ref("int_kippadb__standardized_test_unpivot") }} - where - rn_highest = 1 - and score_type in ( - 'act_reading', - 'act_math', - 'sat_math_test_score', - 'sat_math', - 'sat_reading_test_score', - 'sat_ebrw' - ) - - union all - - select - cast(local_student_id as string) as contact, - - 'PSAT' as test_type, - - score, - - if( - score_type - in ('psat_eb_read_write_section_score', 'psat_reading_test_score'), - 'ELA', - 'Math' - ) as discipline, case - when score_type = 'psat_reading_test_score' - then 'Reading' - when score_type = 'psat_math_section_score' - then 'Math' - when score_type = 'psat_math_test_score' - then 'Math Test' - when score_type = 'psat_eb_read_write_section_score' - then 'EBRW' - end as `subject`, + course_discipline when 'MATH' then 'Math' when 'ENG' then 'ELA' + end as course_discipline, - case - when - score_type in ('psat_reading_test_score', 'psat_math_test_score') - and score >= 21 - then true - when - score_type - in ('psat_math_section_score', 'psat_eb_read_write_section_score') - and score >= 420 - then true - else false - end as met_pathway_requirement, - from {{ ref("int_illuminate__psat_unpivot") }} + -- in some places, we need to know if the score is 10 or NMSQT. not here + if(scope in ('ACT', 'SAT'), scope, 'PSAT') as scope, + + from {{ ref("int_assessments__college_assessment") }} where rn_highest = 1 - and score_type in ( - 'psat_eb_read_write_section_score', - 'psat_math_test_score', - 'psat_math_section_score', - 'psat_reading_test_score' - ) - and test_name != 'PSAT89' + and course_discipline in ('MATH', 'ENG') + and scope != 'PSAT89' ), grad_options_append_final as ( @@ -271,6 +177,7 @@ with cast(a.testscalescore as string) as `value`, if(a.testscalescore >= 725, true, false) as met_pathway_requirement, + from roster as r inner join njgpa_rollup as a on r.state_studentnumber = a.statestudentidentifier @@ -279,37 +186,36 @@ with select r.student_number, - a.discipline, - a.subject, - a.test_type, + a.course_discipline, + a.subject_area, + a.scope as test_type, 'ACT/SAT' as pathway_option, - cast(a.score as string) as `value`, + cast(a.scale_score as string) as `value`, a.met_pathway_requirement, + from roster as r - inner join act_sat_psat_official as a on r.kippadb_contact_id = a.contact - where a.test_type in ('ACT', 'SAT') + inner join act_sat_psat_official as a on r.kippadb_contact_id = a.salesforce_id union all select r.student_number, - a.discipline, - a.subject, - a.test_type, + a.course_discipline, + a.subject_area, + a.scope as test_type, 'PSAT' as pathway_option, - cast(a.score as string) as `value`, + cast(a.scale_score as string) as `value`, a.met_pathway_requirement, + from roster as r - inner join - act_sat_psat_official as a on cast(r.student_number as string) = a.contact - where a.test_type = 'PSAT' + inner join act_sat_psat_official as a on r.student_number = a.student_number union all diff --git a/src/dbt/kipptaf/models/powerschool/intermediate/int_powerschool__state_assessments_transfer_scores.sql b/src/dbt/kipptaf/models/powerschool/intermediate/int_powerschool__state_assessments_transfer_scores.sql new file mode 100644 index 0000000000..e88246b9fe --- /dev/null +++ b/src/dbt/kipptaf/models/powerschool/intermediate/int_powerschool__state_assessments_transfer_scores.sql @@ -0,0 +1,50 @@ +-- purpose of this view: this CTE is used in 2 views - +-- int_students__graduation_path_codes and rpt_tableau__graduation_requirements. this +-- chunk brings over NJGPA scores of students who enrolled with us AFTER they +-- attempted the test. we dont get score files for them because they didnt test with +-- us, but we still need to know: 1) their attempt and, 2) their scores, so that we +-- can calculate graduation eligibility for the grad requirements dash, AND for +-- writing the correct grad path code into PS via autocomm_students. i wasnt sure +-- where this would go, but i figured since all the tables are from PS, it would go +-- here. +select + b._dbt_source_relation, + b.name as test_name, + + s.studentid, + s.grade_level as assessment_grade_level, + + t.numscore as testscalescore, + t.alphascore as testperformancelevel, + + r.name as testcode, + + n.student_number, + n.state_studentnumber, + + case r.name when 'ELAGP' then 'ELA' when 'MATGP' then 'Math' end as discipline, + + case + r.name when 'ELAGP' then 'English Language Arts' when 'MATGP' then 'Mathematics' + end as `subject`, + +from {{ ref("stg_powerschool__test") }} as b +inner join + {{ ref("stg_powerschool__studenttest") }} as s + on b.id = s.testid + and {{ union_dataset_join_clause(left_alias="b", right_alias="s") }} +inner join + {{ ref("stg_powerschool__studenttestscore") }} as t + on s.studentid = t.studentid + and s.id = t.studenttestid + and {{ union_dataset_join_clause(left_alias="s", right_alias="t") }} +inner join + {{ ref("stg_powerschool__testscore") }} as r + on s.testid = r.testid + and t.testscoreid = r.id + and {{ union_dataset_join_clause(left_alias="s", right_alias="r") }} +inner join + {{ ref("stg_powerschool__students") }} as n + on s.studentid = n.id + and {{ union_dataset_join_clause(left_alias="s", right_alias="n") }} +where b.name = 'NJGPA' diff --git a/src/dbt/kipptaf/models/students/intermediate/int_students__graduation_path_codes.sql b/src/dbt/kipptaf/models/students/intermediate/int_students__graduation_path_codes.sql index 5ca1f76c41..6646883379 100644 --- a/src/dbt/kipptaf/models/students/intermediate/int_students__graduation_path_codes.sql +++ b/src/dbt/kipptaf/models/students/intermediate/int_students__graduation_path_codes.sql @@ -19,72 +19,30 @@ with where e.grade_level between 9 and 12 ), - transfer_scores as ( - select - b._dbt_source_relation, - b.name as test_name, - - s.studentid, - s.grade_level as assessment_grade_level, - - t.numscore as testscalescore, - t.alphascore as testperformancelevel, - - r.name as testcode, - case - r.name when 'ELAGP' then 'ELA' when 'MATGP' then 'Math' - end as discipline, - case - r.name - when 'ELAGP' - then 'English Language Arts' - when 'MATGP' - then 'Mathematics' - end as `subject`, - from {{ ref("stg_powerschool__test") }} as b - inner join - {{ ref("stg_powerschool__studenttest") }} as s - on b.id = s.testid - and {{ union_dataset_join_clause(left_alias="b", right_alias="s") }} - inner join - {{ ref("stg_powerschool__studenttestscore") }} as t - on s.studentid = t.studentid - and s.id = t.studenttestid - and {{ union_dataset_join_clause(left_alias="s", right_alias="t") }} - inner join - {{ ref("stg_powerschool__testscore") }} as r - on s.testid = r.testid - and t.testscoreid = r.id - and {{ union_dataset_join_clause(left_alias="s", right_alias="r") }} - where b.name = 'NJGPA' - ), - act_sat_official as ( select - contact, - test_type, + salesforce_id, + scope, case - when score_type in ('act_reading', 'sat_reading_test_score', 'sat_ebrw') - then 'ELA' - when score_type in ('act_math', 'sat_math_test_score', 'sat_math') - then 'Math' - end as discipline, + course_discipline when 'ENG' then 'ELA' when 'MATH' then 'Math' + end as course_discipline, case - when score_type in ('act_reading', 'act_math') and score >= 17 + when score_type in ('act_reading', 'act_math') and scale_score >= 17 then true - when score_type = 'sat_reading_test_score' and score >= 23 + when score_type = 'sat_reading_test_score' and scale_score >= 23 then true - when score_type = 'sat_math_test_score' and score >= 22 + when score_type = 'sat_math_test_score' and scale_score >= 22 then true - when score_type = 'sat_math' and score >= 440 + when score_type = 'sat_math' and scale_score >= 440 then true - when score_type = 'sat_ebrw' and score >= 450 + when score_type = 'sat_ebrw' and scale_score >= 450 then true else false end as met_pathway_requirement, - from {{ ref("int_kippadb__standardized_test_unpivot") }} + + from {{ ref("int_assessments__college_assessment") }} where rn_highest = 1 and score_type in ( @@ -98,66 +56,48 @@ with ), act_sat_pivot as ( - select contact, discipline, act, sat, + select salesforce_id, course_discipline, act, sat, from act_sat_official - pivot (max(met_pathway_requirement) for test_type in ('ACT', 'SAT')) + pivot (max(met_pathway_requirement) for scope in ('ACT', 'SAT')) ), psat_official as ( select - safe_cast(local_student_id as int) as local_student_id, - - if( - score_type - in ('psat_eb_read_write_section_score', 'psat_reading_test_score'), - 'ELA', - 'Math' - ) as discipline, + 'PSAT' as scope, case - when - score_type in ('psat_reading_test_score', 'psat_math_test_score') - and score >= 21 - then true - when - score_type - in ('psat_math_section_score', 'psat_eb_read_write_section_score') - and score >= 420 - then true - else false - end as met_pathway_requirement, - from {{ ref("int_illuminate__psat_unpivot") }} + course_discipline when 'ENG' then 'ELA' when 'MATH' then 'Math' + end as course_discipline, + + safe_cast(student_number as int) as local_student_id, + + if(scale_score >= 420, true, false) as met_pathway_requirement, + + from {{ ref("int_assessments__college_assessment") }} where rn_highest = 1 and score_type in ( - 'psat_eb_read_write_section_score', - 'psat_math_test_score', - 'psat_math_section_score', - 'psat_reading_test_score' + 'psat10_psat_math_section', + 'psatnmsqt_psat_math_section', + 'psat10_psat_ebrw', + 'psatnmsqt_psat_ebrw' ) - and test_name != 'PSAT89' ), psat_rollup as ( - select local_student_id, discipline, max(met_pathway_requirement) as psat, + select + local_student_id, + scope, + course_discipline, + max(met_pathway_requirement) as psat, from psat_official - group by local_student_id, discipline + group by local_student_id, course_discipline, scope ), njgpa as ( - select - s._dbt_source_relation, - s.state_studentnumber, - - x.testscalescore, - x.discipline, - from students as s - left join - transfer_scores as x - on s.studentid = x.studentid - and {{ union_dataset_join_clause(left_alias="s", right_alias="x") }} - where x.studentid is not null + select _dbt_source_relation, state_studentnumber, testscalescore, discipline, + from {{ ref("int_powerschool__state_assessments_transfer_scores") }} union all @@ -209,12 +149,12 @@ with and {{ union_dataset_join_clause(left_alias="r", right_alias="n") }} left join act_sat_pivot as o1 - on r.kippadb_contact_id = o1.contact - and r.discipline = o1.discipline + on r.kippadb_contact_id = o1.salesforce_id + and r.discipline = o1.course_discipline left join psat_rollup as o2 on r.student_number = o2.local_student_id - and r.discipline = o2.discipline + and r.discipline = o2.course_discipline ) select