diff --git a/PowerSlate Integration Fields.docx b/PowerSlate Integration Fields.docx index 97c5dcc..52fd48f 100644 Binary files a/PowerSlate Integration Fields.docx and b/PowerSlate Integration Fields.docx differ diff --git a/SQL/[custom].[PS_selPFAwardsXML].sql b/SQL/[custom].[PS_selPFAwardsXML].sql index 905d96b..37573ad 100644 --- a/SQL/[custom].[PS_selPFAwardsXML].sql +++ b/SQL/[custom].[PS_selPFAwardsXML].sql @@ -14,28 +14,194 @@ GO -- Description: Return XML of award data from PowerFAIDS for the award year associated with a YTS and the tracking status. -- Award data is aggregated and intended for display on Slate dashboards. -- The XML structure mimics Slate's own Dictionary subquery export types for compatibility with Liquid looping. +-- @UseFINAIDMAPPING toggles between selecting a single POE from ACADEMICCALENDAR or selecting multiple POE's from FINAIDMAPPING. +-- PowerFAIDS server/db names may need edited during deployment. -- --- 2022-04-19 Wyatt Best: Removed gross amounts and added total line. +-- 2022-04-19 Wyatt Best: Removed gross amounts and added total line. +-- 2024-05-07 Wyatt Best: Option to use FINAIDMAPPING instead of ACADEMICCALENDAR for POE mappings. +-- Fixed @GovID datatype. +-- Restructured for efficiency. -- ============================================= -CREATE PROCEDURE [custom].[PS_selPFAwardsXML] - -- Add the parameters for the stored procedure here - @PCID NVARCHAR(10) - ,@GovID INT +CREATE PROCEDURE [custom].[PS_selPFAwardsXML] @PCID NVARCHAR(10) + ,@GovID VARCHAR(9) ,@AcademicYear NVARCHAR(4) ,@AcademicTerm NVARCHAR(10) ,@AcademicSession NVARCHAR(10) + ,@UseFINAIDMAPPING BIT = 0 AS BEGIN SET NOCOUNT ON; - DECLARE @FinAidYear NVARCHAR(4) = ( - SELECT FIN_AID_YEAR - FROM ACADEMICCALENDAR - WHERE ACADEMIC_YEAR = @AcademicYear - AND ACADEMIC_TERM = @AcademicTerm - AND ACADEMIC_SESSION = @AcademicSession - ) + DECLARE @student_token INT + ,@FinAidYear INT + ,@TrackStat VARCHAR(2) + DECLARE @POEs TABLE ( + POE INT + ,ACADEMIC_SESSION NVARCHAR(10) + ,award_year INT + ) + DECLARE @AwardsRaw TABLE ( + [fund_long_name] VARCHAR(40) + ,[amount] NUMERIC(8, 2) + ,[attend_desc] VARCHAR(30) + ) + --Find student + SELECT @student_token = student_token + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + WHERE s.alternate_id = @PCID + OR s.student_ssn = @GovID + + --If student not found, quit immediately + IF @student_token IS NULL + BEGIN + SELECT NULL + + RETURN + END + + --Using OR in join criteria for [stu_award_year] caused inefficiency, so queries are repeated + IF @UseFINAIDMAPPING = 1 + BEGIN + --Get POEs from FINAIDMAPPING + INSERT INTO @POEs + SELECT POE + ,ACADEMIC_SESSION + ,NULL + FROM FINAIDMAPPING + WHERE 1 = 1 + AND ACADEMIC_YEAR = @AcademicYear + AND ACADEMIC_TERM = @AcademicTerm + AND ( + ACADEMIC_SESSION = @AcademicSession + OR ACADEMIC_SESSION = '' + ) + AND [STATUS] = 'A' + + --If POE's are mapped by Session, delete POE's with blank session + DELETE + FROM @POEs + WHERE ACADEMIC_SESSION = '' + AND EXISTS ( + SELECT * + FROM @POEs + WHERE ACADEMIC_SESSION > '' + ) + + --Get Aid Year by POE from PowerFAIDS + UPDATE p_local + SET award_year = p_remote.award_year_token + FROM @POEs p_local + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[poe] p_remote + ON p_local.POE = p_remote.poe_token + + --Get tracking status + SELECT @TrackStat = tracking_status + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_year] say + ON say.award_year_token IN ( + SELECT award_year + FROM @POEs + ) + AND s.student_token = say.student_token + WHERE s.student_token = @student_token + + --Get raw award data (multiple POE's method) + INSERT INTO @AwardsRaw + SELECT CASE + WHEN net_disbursement_amount > 0 + AND net_disbursement_amount <> scheduled_amount + THEN fund_long_name + ' (Net)' + ELSE fund_long_name + END [fund_long_name] + ,CASE + WHEN net_disbursement_amount > 0 + AND net_disbursement_amount <> scheduled_amount + THEN net_disbursement_amount + ELSE scheduled_amount + END [amount] + ,CASE + WHEN attend_desc LIKE '%sp%' + THEN 'Spring' + WHEN attend_desc LIKE '%fa%' + THEN 'Fall' + WHEN attend_desc LIKE '%su%' + THEN 'Summer' + END AS [attend_desc] + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_year] say + ON say.award_year_token IN ( + SELECT award_year + FROM @POEs + ) + AND s.student_token = say.student_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award] sa + ON sa.stu_award_year_token = say.stu_award_year_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_transactions] sat + ON sat.stu_award_token = sa.stu_award_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[funds] f + ON f.fund_token = sa.fund_ay_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[poe] + ON poe.poe_token = sat.poe_token + WHERE s.student_token = @student_token + END + ELSE + BEGIN + --Get single POE from ACADEMICCALENDAR + SET @FinAidYear = ( + SELECT FIN_AID_YEAR + FROM ACADEMICCALENDAR + WHERE ACADEMIC_YEAR = @AcademicYear + AND ACADEMIC_TERM = @AcademicTerm + AND ACADEMIC_SESSION = @AcademicSession + ) + + --Get tracking status + SELECT @TrackStat = tracking_status + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_year] say + ON say.award_year_token = @FinAidYear + AND s.student_token = say.student_token + WHERE s.student_token = @student_token + + --Get raw award data (single POE method) + INSERT INTO @AwardsRaw + SELECT CASE + WHEN net_disbursement_amount > 0 + AND net_disbursement_amount <> scheduled_amount + THEN fund_long_name + ' (Net)' + ELSE fund_long_name + END [fund_long_name] + ,CASE + WHEN net_disbursement_amount > 0 + AND net_disbursement_amount <> scheduled_amount + THEN net_disbursement_amount + ELSE scheduled_amount + END [amount] + ,CASE + WHEN attend_desc LIKE '%sp%' + THEN 'Spring' + WHEN attend_desc LIKE '%fa%' + THEN 'Fall' + WHEN attend_desc LIKE '%su%' + THEN 'Summer' + END AS [attend_desc] + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_year] say + ON say.award_year_token = @FinAidYear + AND s.student_token = say.student_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award] sa + ON sa.stu_award_year_token = say.stu_award_year_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_transactions] sat + ON sat.stu_award_token = sa.stu_award_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[funds] f + ON f.fund_token = sa.fund_ay_token + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[poe] + ON poe.poe_token = sat.poe_token + WHERE s.student_token = @student_token + END + + --Format awards as XML SELECT ( SELECT ( SELECT 'fund_long_name' AS [k] @@ -69,37 +235,12 @@ BEGIN ) FROM ( --Individual awards - SELECT * + SELECT [fund_long_name] + ,[Summer] + ,[Fall] + ,[Spring] ,COALESCE([Summer], 0) + COALESCE([Fall], 0) + COALESCE([Spring], 0) AS Total - FROM ( - SELECT CASE - WHEN net_disbursement_amount > 0 - AND net_disbursement_amount <> scheduled_amount - THEN fund_long_name + ' (Net)' - ELSE fund_long_name - END [fund_long_name] - ,CASE - WHEN net_disbursement_amount > 0 - AND net_disbursement_amount <> scheduled_amount - THEN net_disbursement_amount - ELSE scheduled_amount - END [amount] - ,IIF(attend_desc = 'T-Summer', 'Summer', attend_desc) [attend_desc] - FROM [VMCNYPF01].[PFaids].[dbo].[student] s - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award_year] say - ON say.award_year_token = @FinAidYear - AND s.student_token = say.student_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award] sa - ON sa.stu_award_year_token = say.stu_award_year_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award_transactions] sat - ON sat.stu_award_token = sa.stu_award_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[funds] f - ON f.fund_token = sa.fund_ay_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[poe] - ON poe.poe_token = sat.poe_token - WHERE s.alternate_id = @PCID - OR s.student_ssn = @GovID - ) a_raw + FROM @AwardsRaw PIVOT(SUM([amount]) FOR attend_desc IN ( [Summer] ,[Fall] @@ -109,36 +250,12 @@ BEGIN UNION ALL --Grand total - SELECT * + SELECT 'Totals' AS [fund_long_name] + ,[Summer] + ,[Fall] + ,[Spring] ,COALESCE([Summer], 0) + COALESCE([Fall], 0) + COALESCE([Spring], 0) AS Total - FROM ( - SELECT 'Totals' [fund_long_name] - ,CASE - WHEN net_disbursement_amount > 0 - AND net_disbursement_amount <> scheduled_amount - THEN net_disbursement_amount - ELSE scheduled_amount - END [amount] - ,IIF(attend_desc = 'T-Summer', 'Summer', attend_desc) [attend_desc] - FROM [VMCNYPF01].[PFaids].[dbo].[student] s - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award_year] say - ON say.award_year_token = @FinAidYear - AND s.student_token = say.student_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award] sa - ON sa.stu_award_year_token = say.stu_award_year_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award_transactions] sat - ON sat.stu_award_token = sa.stu_award_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[funds] f - ON f.fund_token = sa.fund_ay_token - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[poe] - ON poe.poe_token = sat.poe_token - WHERE ( - s.alternate_id = @PCID - OR s.student_ssn = @GovID - ) - --AND net_disbursement_amount > 0 - --AND net_disbursement_amount <> scheduled_amount - ) a_raw + FROM @AwardsRaw PIVOT(SUM([amount]) FOR attend_desc IN ( [Summer] ,[Fall] @@ -155,11 +272,5 @@ BEGIN FOR XML path('row') ,type ) AS [XML] - ,tracking_status - FROM [VMCNYPF01].[PFaids].[dbo].[student] s - INNER JOIN [VMCNYPF01].[PFaids].[dbo].[stu_award_year] say - ON say.award_year_token = @FinAidYear - AND s.student_token = say.student_token - WHERE s.alternate_id = @PCID - OR s.student_ssn = @GovID + ,@TrackStat AS [tracking_status] END diff --git a/SQL/[custom].[PS_selPFChecklist].sql b/SQL/[custom].[PS_selPFChecklist].sql index bf2497b..36a4df6 100644 --- a/SQL/[custom].[PS_selPFChecklist].sql +++ b/SQL/[custom].[PS_selPFChecklist].sql @@ -11,10 +11,12 @@ GO -- Author: Wyatt Best -- Create date: 2020-09-30 -- Description: Selects a list of missing documents from PowerFAIDS. --- award_year_token in PowerFAIDS is pulled from FIN_AID_YEAR in ACADEMICCALENDAR. +-- @UseFINAIDMAPPING toggles between selecting a single POE from ACADEMICCALENDAR (0) or selecting multiple POE's (1) from FINAIDMAPPING. +-- PowerFAIDS server/db names may need edited during deployment. -- -- 2020-11-12 Wyatt Best: Added search by TIN/SSN (@GovID) instead of just PEOPLE_CODE_ID (@PCID). -- 2021-04-02 Wyatt Best: Changed @GovID datatype from INT to match PFaids column. +-- 2024-05-07 Wyatt Best: Option to use FINAIDMAPPING instead of ACADEMICCALENDAR for POE mappings. -- ============================================= CREATE PROCEDURE [custom].[PS_selPFChecklist] @PCID NVARCHAR(10) @@ -22,32 +24,102 @@ CREATE PROCEDURE [custom].[PS_selPFChecklist] ,@AcademicYear NVARCHAR(4) ,@AcademicTerm NVARCHAR(10) ,@AcademicSession NVARCHAR(10) + ,@UseFINAIDMAPPING BIT = 0 AS BEGIN SET NOCOUNT ON; - DECLARE @FinAidYear NVARCHAR(4) = ( - SELECT FIN_AID_YEAR - FROM ACADEMICCALENDAR - WHERE ACADEMIC_YEAR = @AcademicYear - AND ACADEMIC_TERM = @AcademicTerm - AND ACADEMIC_SESSION = @AcademicSession - ) + DECLARE @student_token INT + ,@FinAidYear INT + DECLARE @POEs TABLE ( + POE INT + ,ACADEMIC_SESSION NVARCHAR(10) + ,award_year INT + ) + + --Find student + SELECT @student_token = student_token + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + WHERE s.alternate_id = @PCID + OR s.student_ssn = @GovID + + --If student not found, quit immediately + IF @student_token IS NULL + BEGIN + SELECT NULL + + RETURN + END + + IF @UseFINAIDMAPPING = 1 + BEGIN + --Get POEs from FINAIDMAPPING + INSERT INTO @POEs + SELECT POE + ,ACADEMIC_SESSION + ,NULL + FROM FINAIDMAPPING + WHERE 1 = 1 + AND ACADEMIC_YEAR = @AcademicYear + AND ACADEMIC_TERM = @AcademicTerm + AND ( + ACADEMIC_SESSION = @AcademicSession + OR ACADEMIC_SESSION = '' + ) + AND [STATUS] = 'A' + + --If POE's are mapped by Session, delete POE's with blank session + DELETE + FROM @POEs + WHERE ACADEMIC_SESSION = '' + AND EXISTS ( + SELECT * + FROM @POEs + WHERE ACADEMIC_SESSION > '' + ) + + --Get Aid Year by POE from PowerFAIDS + UPDATE p_local + SET award_year = p_remote.award_year_token + FROM @POEs p_local + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[poe] p_remote + ON p_local.POE = p_remote.poe_token + END + ELSE + BEGIN + --Get single POE from ACADEMICCALENDAR + SET @FinAidYear = ( + SELECT FIN_AID_YEAR + FROM ACADEMICCALENDAR + WHERE ACADEMIC_YEAR = @AcademicYear + AND ACADEMIC_TERM = @AcademicTerm + AND ACADEMIC_SESSION = @AcademicSession + ) + END SELECT srd.doc_token [Code] --,d.doc_name ,doc_status_desc [Status] ,FORMAT(status_effective_dt, 'yyyy-MM-dd') [Date] - FROM [PFaids].[dbo].[student] s - INNER JOIN [PFaids].[dbo].[stu_award_year] say - ON say.award_year_token = @FinAidYear + FROM [POWERFAIDS].[PFaids].[dbo].[student] s + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[stu_award_year] say + ON ( + @UseFINAIDMAPPING = 0 + AND say.award_year_token = @FinAidYear + ) + OR ( + @UseFINAIDMAPPING = 1 + AND say.award_year_token IN ( + SELECT award_year + FROM @POEs + ) + ) AND s.student_token = say.student_token - INNER JOIN [PFaids].[dbo].[student_required_documents] srd + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[student_required_documents] srd ON say.stu_award_year_token = srd.stu_award_year_token - INNER JOIN [PFaids].[dbo].[docs] d + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[docs] d ON d.doc_token = srd.doc_token - INNER JOIN [PFaids].[dbo].[doc_status_code] dsc + INNER JOIN [POWERFAIDS].[PFaids].[dbo].[doc_status_code] dsc ON dsc.doc_required_status_code = srd.doc_status - WHERE s.alternate_id = @PCID - OR s.student_ssn = @GovID + WHERE s.student_token = @student_token END diff --git a/SQL/[custom].[PS_selProfile].sql b/SQL/[custom].[PS_selProfile].sql index 3d3d190..7497323 100644 --- a/SQL/[custom].[PS_selProfile].sql +++ b/SQL/[custom].[PS_selProfile].sql @@ -26,6 +26,7 @@ GO -- 2021-12-01 Wyatt Best: Renamed MoodleOrientationComplete to custom_1 and added 4 more custom fields. -- 2022-02-16 Wyatt Best: Added @EmailType parameter. -- 2022-09-27 Wyatt Best: Return AD username (SSO ID) to Slate from PersonUser. +-- 2024-03-29 Wyatt Best: Return Guid column (new in 9.2.3) or error message about changed YTSPDC. -- ============================================= CREATE PROCEDURE [custom].[PS_selProfile] @PCID NVARCHAR(10) ,@Year NVARCHAR(4) @@ -35,10 +36,16 @@ CREATE PROCEDURE [custom].[PS_selProfile] @PCID NVARCHAR(10) ,@Degree NVARCHAR(6) ,@Curriculum NVARCHAR(6) ,@EmailType NVARCHAR(10) + ,@AcademicGuid UNIQUEIDENTIFIER AS BEGIN SET NOCOUNT ON; + --Writing a simple method for handling non-fatal errors because differentiating real + --errors in Python is hard and varies based on the ODBC driver used. + DECLARE @ErrorFlag BIT = 0 + ,@ErrorMessage NVARCHAR(max) + --Error check IF ( @EmailType IS NOT NULL @@ -59,10 +66,10 @@ BEGIN RETURN END - --Select credits from rollup to avoid duplicate hits to table + --Select credits from rollup DECLARE @Credits NUMERIC(6, 2) = ( SELECT CREDITS - FROM ACADEMIC A + FROM ACADEMIC WHERE PEOPLE_CODE_ID = @PCID AND ACADEMIC_YEAR = @Year AND ACADEMIC_TERM = @Term @@ -72,87 +79,146 @@ BEGIN AND CURRICULUM = @Curriculum ) - --If someone has multiple apps for one YTS with different PDC's but the same transcript sequence, you will not be able to - --separate the credits because TRANSCRIPTDETAIL doesn't have PDC. Custom logic is required to sort out things like-zero credit certificate - --dual enrollment with a for-credit program. - SELECT CASE - WHEN @Credits > 0 - THEN 'Y' - WHEN PROGRAM = 'CERT' - AND EXISTS ( - SELECT TD.PEOPLE_ID - FROM TRANSCRIPTDETAIL TD - INNER JOIN ACADEMIC A - ON A.PEOPLE_CODE_ID = TD.PEOPLE_CODE_ID - AND A.ACADEMIC_YEAR = TD.ACADEMIC_YEAR - AND A.ACADEMIC_TERM = TD.ACADEMIC_TERM - AND A.ACADEMIC_SESSION = TD.ACADEMIC_SESSION - AND A.PROGRAM = @Program - AND A.DEGREE = @Degree - AND A.CURRICULUM = @Curriculum - AND A.TRANSCRIPT_SEQ = TD.TRANSCRIPT_SEQ - --AND A.ACADEMIC_FLAG = 'Y' --Can mask some issues of registrations w/out acceptance, but needed for someone who applies for CERT and UNDER and only registers for undergrad. - AND A.APPLICATION_FLAG = 'Y' - WHERE TD.PEOPLE_CODE_ID = @PCID - AND TD.ACADEMIC_YEAR = @Year - AND TD.ACADEMIC_TERM = @Term - AND TD.ACADEMIC_SESSION = @Session - AND TD.ADD_DROP_WAIT = 'A' - ) - THEN 'Y' - ELSE 'N' - END AS 'Registered' - ,CAST(COALESCE(PREREG_VAL_DATE, REG_VAL_DATE) AS DATE) [REG_VAL_DATE] - ,cast(@Credits AS VARCHAR(6)) AS CREDITS - ,A.COLLEGE_ATTEND - ,( - SELECT REQUIRE_SEPDATE - FROM CODE_ENROLLMENT - WHERE CODE_VALUE_KEY = A.ENROLL_SEPARATION - ) AS Withdrawn - ,oE.Email AS CampusEmail - ,( - SELECT NonQualifiedUserName - FROM PersonUser - WHERE PersonId = dbo.fnGetPersonId(A.ADVISOR) - ) [AdvisorUsername] - ,( - SELECT NonQualifiedUserName - FROM PersonUser - WHERE PersonId = dbo.fnGetPersonId(A.PEOPLE_CODE_ID) - ) [Username] - ,CASE - WHEN EXISTS ( - SELECT * - FROM TESTSCORES T - WHERE TEST_ID = 'MOOD' - AND TEST_TYPE = 'STU' - AND ALPHA_SCORE_1 = 'P' - AND T.PEOPLE_CODE_ID = A.PEOPLE_CODE_ID - ) - THEN 'Y' - ELSE 'N' - END [custom_1] - ,NULL [custom_2] - ,NULL [custom_3] - ,NULL [custom_4] - ,NULL [custom_5] - FROM ACADEMIC A - OUTER APPLY ( - SELECT TOP 1 Email - FROM EmailAddress E - WHERE E.PeopleOrgCodeId = A.PEOPLE_CODE_ID - AND E.EmailType = @EmailType - AND E.IsActive = 1 - ORDER BY E.REVISION_DATE DESC - ,REVISION_TIME DESC - ) oE - WHERE PEOPLE_CODE_ID = @PCID - AND ACADEMIC_YEAR = @Year - AND ACADEMIC_TERM = @Term - AND ACADEMIC_SESSION = @Session - AND PROGRAM = @Program - AND DEGREE = @Degree - AND CURRICULUM = @Curriculum - AND APPLICATION_FLAG = 'Y' --Ought to be an application, or there's a problem somewhere. + --Search for @AcademicGuid if NULL + IF @AcademicGuid IS NULL + SELECT @AcademicGuid = [Guid] + FROM ACADEMIC + WHERE PEOPLE_CODE_ID = @PCID + AND ACADEMIC_YEAR = @Year + AND ACADEMIC_TERM = @Term + AND ACADEMIC_SESSION = @Session + AND PROGRAM = @Program + AND DEGREE = @Degree + AND CURRICULUM = @Curriculum + ELSE + BEGIN + --Verify that YTSPDC match existing @AcademicGuid + DECLARE @TempYear NVARCHAR(4) + ,@TempTerm NVARCHAR(10) + ,@TempSession NVARCHAR(10) + ,@TempProgram NVARCHAR(6) + ,@TempDegree NVARCHAR(6) + ,@TempCurriculum NVARCHAR(6) + + SELECT @TempYear = ACADEMIC_YEAR + ,@TempTerm = ACADEMIC_TERM + ,@TempSession = ACADEMIC_SESSION + ,@TempProgram = PROGRAM + ,@TempDegree = DEGREE + ,@TempCurriculum = CURRICULUM + FROM [ACADEMIC] + WHERE [Guid] = @AcademicGuid + + IF @TempYear <> @Year + OR @TempTerm <> @Term + OR @TempSession <> @Session + OR @TempProgram <> @Program + OR @TempDegree <> @Degree + OR @TempCurriculum <> @Curriculum + SELECT @ErrorFlag = 1 + ,@ErrorMessage = 'The Application in PowerCampus has a different YTS + PDC than the Slate application.
+ Expected: ' + @Year + '/' + @Term + '/' + @Session + '/' + @Program + '/' + @Degree + '/' + @Curriculum + '
+ Found: ' + @TempYear + '/' + @TempTerm + '/' + @TempSession + '/' + @TempProgram + '/' + @TempDegree + '/' + @TempCurriculum + END + + --Return error if @ErrorFlag = 1 + IF @ErrorFlag = 1 + SELECT NULL [Registered] + ,NULL [REG_VAL_DATE] + ,NULL [CREDITS] + ,NULL [COLLEGE_ATTEND] + ,NULL [Withdrawn] + ,NULL [CampusEmail] + ,NULL [AdvisorUsername] + ,NULL [Username] + ,NULL [custom_1] + ,NULL [custom_2] + ,NULL [custom_3] + ,NULL [custom_4] + ,NULL [custom_5] + ,@ErrorFlag [ErrorFlag] + ,@ErrorMessage [ErrorMessage] + ELSE + BEGIN + --Else return ACADEMIC columns + -- + --If someone has multiple apps for one YTS with different PDC's but the same transcript sequence, you will not be able to + --separate the credits because TRANSCRIPTDETAIL doesn't have PDC. Custom logic is required to sort out things like-zero credit certificate + --dual enrollment with a for-credit program. + SELECT CASE + WHEN @Credits > 0 + THEN 'Y' + WHEN PROGRAM = 'CERT' + AND EXISTS ( + SELECT TD.PEOPLE_ID + FROM TRANSCRIPTDETAIL TD + INNER JOIN ACADEMIC A + ON A.[Guid] = @AcademicGuid + --A.PEOPLE_CODE_ID = TD.PEOPLE_CODE_ID + --AND A.ACADEMIC_YEAR = TD.ACADEMIC_YEAR + --AND A.ACADEMIC_TERM = TD.ACADEMIC_TERM + --AND A.ACADEMIC_SESSION = TD.ACADEMIC_SESSION + --AND A.PROGRAM = @Program + --AND A.DEGREE = @Degree + --AND A.CURRICULUM = @Curriculum + --AND A.TRANSCRIPT_SEQ = TD.TRANSCRIPT_SEQ + --AND A.ACADEMIC_FLAG = 'Y' --Can mask some issues of registrations w/out acceptance, but needed for someone who applies for CERT and UNDER and only registers for undergrad. + AND A.APPLICATION_FLAG = 'Y' + WHERE TD.PEOPLE_CODE_ID = @PCID + AND TD.ACADEMIC_YEAR = @Year + AND TD.ACADEMIC_TERM = @Term + AND TD.ACADEMIC_SESSION = @Session + AND TD.ADD_DROP_WAIT = 'A' + ) + THEN 'Y' + ELSE 'N' + END AS [Registered] + ,CAST(COALESCE(PREREG_VAL_DATE, REG_VAL_DATE) AS DATE) AS [REG_VAL_DATE] + ,cast(@Credits AS VARCHAR(6)) AS [CREDITS] + ,A.[COLLEGE_ATTEND] + ,( + SELECT REQUIRE_SEPDATE + FROM CODE_ENROLLMENT + WHERE CODE_VALUE_KEY = A.ENROLL_SEPARATION + ) AS [Withdrawn] + ,oE.Email AS [CampusEmail] + ,( + SELECT NonQualifiedUserName + FROM PersonUser + WHERE PersonId = dbo.fnGetPersonId(A.ADVISOR) + ) AS [AdvisorUsername] + ,( + SELECT NonQualifiedUserName + FROM PersonUser + WHERE PersonId = dbo.fnGetPersonId(A.PEOPLE_CODE_ID) + ) AS [Username] + ,[Guid] + ,NULL [custom_1] + ,NULL [custom_2] + ,NULL [custom_3] + ,NULL [custom_4] + ,NULL [custom_5] + ,@ErrorFlag [ErrorFlag] + ,@ErrorMessage [ErrorMessage] + FROM ACADEMIC A + OUTER APPLY ( + SELECT TOP 1 Email + FROM EmailAddress E + WHERE E.PeopleOrgCodeId = A.PEOPLE_CODE_ID + AND E.EmailType = @EmailType + AND E.IsActive = 1 + ORDER BY E.REVISION_DATE DESC + ,REVISION_TIME DESC + ) oE + WHERE 1 = 1 + AND [Guid] = @AcademicGuid + --AND PEOPLE_CODE_ID = @PCID + --AND ACADEMIC_YEAR = @Year + --AND ACADEMIC_TERM = @Term + --AND ACADEMIC_SESSION = @Session + --AND PROGRAM = @Program + --AND DEGREE = @Degree + --AND CURRICULUM = @Curriculum + AND APPLICATION_FLAG = 'Y' --Ought to be an application, or there's a problem somewhere. + END END diff --git a/SQL/[custom].[PS_updAcademicAppInfo].sql b/SQL/[custom].[PS_updAcademicAppInfo].sql index 1c9d748..cdc8a2c 100644 --- a/SQL/[custom].[PS_updAcademicAppInfo].sql +++ b/SQL/[custom].[PS_updAcademicAppInfo].sql @@ -12,8 +12,8 @@ GO -- Author: Wyatt Best -- Create date: 2016-11-17 -- Description: Updates Status and Decision code for application from Slate. --- Sets ACADEMIC_FLAG, PRIMARY_FLAG, ENROLL_SEPARATION, DEPARTMENT, POPULATION, COUNSELOR, EXTRA_CURRICULAR, COLLEGE_ATTEND, APPLICATION_DATE. --- Sets ADMIT and MATRIC field groups. +-- Sets ACADEMIC_FLAG, PRIMARY_FLAG, ENROLL_SEPARATION, COLLEGE, DEPARTMENT, POPULATION, COUNSELOR, EXTRA_CURRICULAR, COLLEGE_ATTEND, APPLICATION_DATE. +-- Sets ADMIT and MATRIC field groups. Sets PROGRAM_START_DATE. -- -- 2016-12-15 Wyatt Best: Added 'Defer' ProposedDecision type. -- 2016-12-28 Wyatt Best: Changed translation CODE_APPDECISION for Waiver from 'ACCP' to 'WAIV' @@ -40,6 +40,8 @@ GO -- If ACADEMIC_FLAG isn't yet set to Y, update ACADEMIC.ORG_CODE_ID based on the passed OrganizationId. -- 2021-12-13 Wyatt Best: Ability to set NONTRAD_PROGRAM back to blank (NULL isn't allowed). Formerly, a bad @Nontraditional value later set to NULL in Slate would remain in PowerCampus. -- 2023-03-02 Wyatt Best: Use ADM_APPLICANT_DEFAULT setting instead of STUDENT_CODING_ENROLLED setting for ENROLL_SEPARATION when converting to student. +-- 2024-05-03 Wyatt Best: Added @College. +-- 2024-05-10 Wyatt Best: Added flag @SetProgramStartDate to default program start date from academic calendar. -- ============================================= CREATE PROCEDURE [custom].[PS_updAcademicAppInfo] @PCID NVARCHAR(10) ,@Year NVARCHAR(4) @@ -48,6 +50,7 @@ CREATE PROCEDURE [custom].[PS_updAcademicAppInfo] @PCID NVARCHAR(10) ,@Program NVARCHAR(6) ,@Degree NVARCHAR(6) ,@Curriculum NVARCHAR(6) + ,@College NVARCHAR(6) NULL ,@Department NVARCHAR(10) NULL ,@Nontraditional NVARCHAR(6) NULL ,@Population NVARCHAR(12) NULL @@ -62,6 +65,7 @@ CREATE PROCEDURE [custom].[PS_updAcademicAppInfo] @PCID NVARCHAR(10) ,@CollegeAttend NVARCHAR(4) NULL ,@Extracurricular BIT NULL ,@CreateDateTime DATETIME --Application creation date + ,@SetProgramStartDate BIT NULL AS BEGIN SET NOCOUNT ON; @@ -95,6 +99,25 @@ BEGIN END --Error checks + IF ( + @College IS NOT NULL + AND NOT EXISTS ( + SELECT * + FROM CODE_COLLEGE + WHERE CODE_VALUE_KEY = @College + ) + ) + BEGIN + RAISERROR ( + '@College ''%s'' not found in CODE_COLLEGE.' + ,11 + ,1 + ,@College + ) + + RETURN + END + IF ( @Department IS NOT NULL AND NOT EXISTS ( @@ -294,6 +317,22 @@ BEGIN AND @AppStatus IS NOT NULL AND @AppDecision IS NOT NULL + --Update COLLEGE if needed + UPDATE ACADEMIC + SET COLLEGE = @College + WHERE PEOPLE_CODE_ID = @PCID + AND ACADEMIC_YEAR = @Year + AND ACADEMIC_TERM = @Term + AND ACADEMIC_SESSION = @Session + AND PROGRAM = @Program + AND DEGREE = @Degree + AND CURRICULUM = @Curriculum + AND APPLICATION_FLAG = 'Y' + AND ( + COLLEGE <> @College + OR COLLEGE IS NULL + ) + --Update DEPARTMENT if needed UPDATE ACADEMIC SET DEPARTMENT = @Department @@ -339,7 +378,7 @@ BEGIN ) BEGIN --ENROLL_SEPARATION is only updated if the ACADEMIC_FLAG is toggled, otherwise it's left alone. - DECLARE @ConvertedStudentCode NVARCHAR(8) = dbo.fnGetAbtSetting('ADM_APPLICANT_DEFAULT','APPLICANT_SETUP_DEFAULT','CONVERTED_STUDENT_ENROLLSEP') + DECLARE @ConvertedStudentCode NVARCHAR(8) = dbo.fnGetAbtSetting('ADM_APPLICANT_DEFAULT', 'APPLICANT_SETUP_DEFAULT', 'CONVERTED_STUDENT_ENROLLSEP') ,@NewAcademicFlag NVARCHAR(1) = ( SELECT CASE WHEN EXISTS ( @@ -617,5 +656,19 @@ BEGIN AND APPLICATION_FLAG = 'Y' AND COALESCE(APPLICATION_DATE, '') <> dbo.fnMakeDate(@CreateDateTime); + --Update PROGRAM_START_DATE if needed + UPDATE ACADEMIC + SET PROGRAM_START_DATE = @MatricDate + WHERE PEOPLE_CODE_ID = @PCID + AND ACADEMIC_YEAR = @Year + AND ACADEMIC_TERM = @Term + AND ACADEMIC_SESSION = @Session + AND PROGRAM = @Program + AND DEGREE = @Degree + AND CURRICULUM = @Curriculum + AND APPLICATION_FLAG = 'Y' + AND PROGRAM_START_DATE IS NULL + AND @SetProgramStartDate = 1 + COMMIT END diff --git a/SQL/[custom].[PS_updAcademicKey].sql b/SQL/[custom].[PS_updAcademicKey].sql index aa00a70..4dad871 100644 --- a/SQL/[custom].[PS_updAcademicKey].sql +++ b/SQL/[custom].[PS_updAcademicKey].sql @@ -11,11 +11,13 @@ GO -- ============================================= -- Author: Wyatt Best -- Create date: 2021-03-17 --- Description: Updates [custom].AcademicKey with RecruiterApplicationId. See https://github.com/WyattBest/PowerCampus-AcademicKey --- Updates PROGRAM, DEGREE, and CURRICULUM rows in ACADEMIC if program change happens in Slate before registration or academic plan assignment. +-- Description: Updates PROGRAM, DEGREE, and CURRICULUM rows in ACADEMIC if program change happens in Slate before registration or academic plan assignment. +-- Set APPLICATION_FLAG to 'Y' if necessary (fix rows manually entered in Academic Records before application was inserted). -- -- 2021-09-01 Wyatt Best: Clear bad RecruiterApplicationId entries. -- 2022-04-04 Wyatt Best: Add ability to update PROGRAM/DEGREE/CURRICULUM in ACADEMIC. Stop clearing bad RecruiterApplicationId entries. +-- 2024-03-29 Wyatt Best: Rewritten to use 9.2.3's built-in Academic.Guid instead of a custom key. Formerly used https://github.com/WyattBest/PowerCampus-AcademicKey. +-- Set APPLICATION_FLAG to 'Y' if necessary. -- ============================================= CREATE PROCEDURE [custom].[PS_updAcademicKey] @PCID NVARCHAR(10) ,@Year NVARCHAR(4) @@ -24,94 +26,44 @@ CREATE PROCEDURE [custom].[PS_updAcademicKey] @PCID NVARCHAR(10) ,@Program NVARCHAR(6) ,@Degree NVARCHAR(6) ,@Curriculum NVARCHAR(6) - ,@SlateAppGuid UNIQUEIDENTIFIER NULL + ,@AcademicGuid UNIQUEIDENTIFIER NULL AS BEGIN SET NOCOUNT ON; - DECLARE @RecruiterApplicationId INT = ( - SELECT RecruiterApplicationId - FROM RecruiterApplication - WHERE ApplicationNumber = @SlateAppGuid - AND ApplicationId IS NOT NULL - ) - - IF @RecruiterApplicationId IS NOT NULL - BEGIN - -- Find ACADEMIC row ID - DECLARE @AcademicGuid UNIQUEIDENTIFIER = ( - SELECT [id] - FROM [custom].AcademicKey - WHERE RecruiterApplicationId = @RecruiterApplicationId - ) - - IF @AcademicGuid IS NOT NULL - BEGIN - -- Potentially update ACADEMIC row PDC - UPDATE A - SET PROGRAM = @Program - ,DEGREE = @Degree - ,CURRICULUM = @Curriculum - FROM ACADEMIC A - INNER JOIN [custom].academickey AK - ON AK.PEOPLE_CODE_ID = A.PEOPLE_CODE_ID - AND AK.ACADEMIC_YEAR = A.ACADEMIC_YEAR - AND AK.ACADEMIC_SESSION = A.ACADEMIC_SESSION - AND AK.ACADEMIC_TERM = A.ACADEMIC_TERM - AND AK.PROGRAM = A.PROGRAM - AND AK.DEGREE = A.DEGREE - AND AK.CURRICULUM = A.CURRICULUM - WHERE 1 = 1 - AND AK.ID = @AcademicGuid - AND A.PEOPLE_CODE_ID = @PCID - AND A.ACADEMIC_YEAR = @Year - AND A.ACADEMIC_SESSION = @Session - AND A.ACADEMIC_TERM = @Term - AND ( - A.PROGRAM <> @Program - OR A.DEGREE <> @Degree - OR A.CURRICULUM <> @Curriculum - ) - AND [STATUS] <> 'N' - AND APPLICATION_FLAG = 'Y' - AND CREDITS = 0 - AND REG_VALIDATE = 'N' - AND PREREG_VALIDATE = 'N' - AND ACA_PLAN_SETUP = 'N' - END - - ---- Find and clear RecruiterApplicationId from [custom].AcademicKey if not matched - --UPDATE [custom].AcademicKey - --SET RecruiterApplicationId = NULL - --WHERE RecruiterApplicationId = @RecruiterApplicationId - -- AND ( - -- PEOPLE_CODE_ID <> @PCID - -- OR ACADEMIC_YEAR <> @Year - -- OR ACADEMIC_TERM <> @Term - -- OR ACADEMIC_SESSION <> @Session - -- OR PROGRAM <> @Program - -- OR DEGREE <> @Degree - -- OR CURRICULUM <> @Curriculum - -- ) - -- Update AcademicKey if needed - IF NOT EXISTS ( - SELECT * - FROM RecruiterApplication RA - INNER JOIN [custom].AcademicKey AK - ON AK.RecruiterApplicationId = RA.RecruiterApplicationId - WHERE RA.ApplicationNumber = @SlateAppGuid + IF @AcademicGuid IS NOT NULL + --If the GUID is provided, potentially update PDC and APPLICATION_FLAG + UPDATE A + SET PROGRAM = @Program + ,DEGREE = @Degree + ,CURRICULUM = @Curriculum + ,APPLICATION_FLAG = 'Y' + FROM ACADEMIC A + WHERE 1 = 1 + AND A.[Guid] = @AcademicGuid + AND ( + A.PROGRAM <> @Program + OR A.DEGREE <> @Degree + OR A.CURRICULUM <> @Curriculum + OR A.APPLICATION_FLAG <> 'Y' ) - UPDATE AK - SET AK.RecruiterApplicationId = RA.RecruiterApplicationId - FROM [custom].AcademicKey AK - INNER JOIN RecruiterApplication RA - ON RA.ApplicationNumber = @SlateAppGuid - WHERE PEOPLE_CODE_ID = @PCID - AND ACADEMIC_YEAR = @Year - AND ACADEMIC_TERM = @Term - AND ACADEMIC_SESSION = @Session - AND PROGRAM = @Program - AND DEGREE = @Degree - AND CURRICULUM = @Curriculum - END + AND [STATUS] <> 'N' + AND CREDITS = 0 + AND REG_VALIDATE = 'N' + AND PREREG_VALIDATE = 'N' + AND ACA_PLAN_SETUP = 'N' + ELSE + --If the GUID is not provided, update APPLICATION_FLAG based on the provided YTSPDC + UPDATE ACADEMIC + SET APPLICATION_FLAG = 'Y' + WHERE 1 = 1 + AND PEOPLE_CODE_ID = @PCID + AND ACADEMIC_YEAR = @Year + AND ACADEMIC_SESSION = @Session + AND ACADEMIC_TERM = @Term + AND PROGRAM = @Program + AND DEGREE = @Degree + AND CURRICULUM = @Curriculum + AND [STATUS] <> 'N' + AND APPLICATION_FLAG <> 'Y' END diff --git a/SQL/[custom].[PS_updDemographics].sql b/SQL/[custom].[PS_updDemographics].sql index 8470cee..cb02274 100644 --- a/SQL/[custom].[PS_updDemographics].sql +++ b/SQL/[custom].[PS_updDemographics].sql @@ -23,10 +23,12 @@ GO -- 2021-09-01 Wyatt Best: Named transaction. -- 2023-10-05 Rafael Gomez: Added @Religion. -- 2023-11-09 Wyatt Best: Updated error message when GOVERNMENT_ID already assigned to other record. +-- 2024-04-10 Wyatt Best: Updated for 9.2.3 changes to [WebServices].[spSetDemographics]'s @Gender parameter. +-- Default Legal Name if blank. -- ============================================= CREATE PROCEDURE [custom].[PS_updDemographics] @PCID NVARCHAR(10) ,@Opid NVARCHAR(8) - ,@Gender TINYINT + ,@GenderId TINYINT ,@Ethnicity TINYINT --0 = None, 1 = Hispanic, 2 = NonHispanic. Ellucian's API was supposed to record nothing for ethnicity for 0. I don't think it supports multi-value, but this sproc does. ,@DemographicsEthnicity NVARCHAR(6) ,@MaritalStatus NVARCHAR(4) NULL @@ -56,6 +58,25 @@ BEGIN ,@Now DATETIME = dbo.fnMakeTime(@getdate) --Error check + IF ( + @GenderId IS NOT NULL + AND NOT EXISTS ( + SELECT * + FROM CODE_GENDER + WHERE GenderId = @GenderId + ) + ) + BEGIN + RAISERROR ( + '@GenderId %d not found in CODE_ETHNICITY.' + ,11 + ,1 + ,@GenderId + ) + + RETURN + END + IF ( @DemographicsEthnicity IS NOT NULL AND NOT EXISTS ( @@ -112,7 +133,7 @@ BEGIN RETURN END - + DECLARE @DupPCID NVARCHAR(10) = ( SELECT TOP 1 PEOPLE_CODE_ID FROM PEOPLE @@ -124,6 +145,14 @@ BEGIN FROM PEOPLE WHERE PEOPLE_CODE_ID = @PCID ) + DECLARE @GenderCode NVARCHAR(1) + ,@GenderMed NVARCHAR(20) + + SELECT @GenderCode = CODE_VALUE_KEY + ,@GenderMed = MEDIUM_DESC + FROM CODE_GENDER + WHERE GenderId = @GenderId + --Treat blanks as NULL SET @ExistingGovId = NULLIF(@ExistingGovId, '') @@ -193,7 +222,7 @@ BEGIN AND NOT EXISTS (SELECT PersonId, IpedsFederalCategoryId FROM PersonEthnicity WHERE PersonId = @PersonId and IpedsFederalCategoryId = 6)) EXEC [custom].[PS_insPersonEthnicity] @PersonId, @Opid, @Today, @Now, 6; - + --Update DEMOGRAPHICS rollup if needed IF NOT EXISTS ( SELECT * @@ -202,20 +231,23 @@ BEGIN AND ACADEMIC_YEAR = '' AND ACADEMIC_TERM = '' AND ACADEMIC_SESSION = '' - AND GENDER = @Gender + AND GENDER = @GenderCode AND ETHNICITY = @DemographicsEthnicity AND MARITAL_STATUS = @MaritalStatus AND VETERAN = @Veteran AND CITIZENSHIP = @PrimaryCitizenship AND DUAL_CITIZENSHIP = @SecondaryCitizenship AND PRIMARY_LANGUAGE = @PrimaryLanguage - and HOME_LANGUAGE = @HomeLanguage + AND HOME_LANGUAGE = @HomeLanguage AND RELIGION = @Religion ) - EXECUTE [WebServices].[spSetDemographics] @PersonId + BEGIN + DECLARE @return_value INT + + EXECUTE @return_value = [WebServices].[spSetDemographics] @PersonId ,@Opid ,'001' - ,@Gender + ,@GenderMed ,@DemographicsEthnicity ,@MaritalStatus ,@Religion @@ -229,6 +261,20 @@ BEGIN ,@HomeLanguage ,NULL + --Ellucian stopped raising errors in spSetDemographics and just returns an int?? + --Probably some modern trend to make it harder for end users to see meaningful error messages. + IF @return_value <> 0 + BEGIN + RAISERROR ( + 'WebServices.spSetDemographics returned error code %d.' + ,11 + ,1 + ,@return_value + ) + + RETURN + END + END --Update GOVERNMENT_ID if needed. IF @GovernmentId IS NOT NULL @@ -242,6 +288,15 @@ BEGIN SET GOVERNMENT_ID = @GovernmentId WHERE PEOPLE_CODE_ID = @PCID + --Update Legal Name if blank + UPDATE PEOPLE + SET LegalName = dbo.fnPeopleOrgName(@PCID, 'LN, |FN |MN, |SX') + WHERE PEOPLE_CODE_ID = @PCID + AND ( + LegalName = '' + OR LegalName IS NULL + ) + COMMIT TRANSACTION PS_updDemographics END GO diff --git a/SQL/[custom].[PS_updProgramOfStudy].sql b/SQL/[custom].[PS_updProgramOfStudy].sql index 93e99f1..272de7a 100644 --- a/SQL/[custom].[PS_updProgramOfStudy].sql +++ b/SQL/[custom].[PS_updProgramOfStudy].sql @@ -11,13 +11,16 @@ GO -- ============================================= -- Author: Wyatt Best -- Create date: 2021-05-17 --- Description: Inserts a PDC combination into ProgramOfStudy if it doesn't already exist. +-- Description: Inserts a PDC combination into ProgramOfStudy and ApplicationProgramSetting if it doesn't already exist. -- If @DegReqMinYear is not null, PDC combination will be valided against DEGREQ. +-- +-- 2024-03-21 Wyatt Best: Also insert into ApplicationProgramSetting. -- ============================================= CREATE PROCEDURE [custom].[PS_updProgramOfStudy] @Program NVARCHAR(6) ,@Degree NVARCHAR(6) ,@Curriculum NVARCHAR(6) ,@DegReqMinYear NVARCHAR(4) = NULL + ,@AppFormSettingId INT AS BEGIN SET NOCOUNT ON; @@ -36,7 +39,7 @@ BEGIN SELECT CurriculumId FROM CODE_CURRICULUM WHERE CODE_VALUE_KEY = @Curriculum - ) + ); --Error checks IF @ProgramId IS NULL @@ -92,14 +95,17 @@ BEGIN RETURN END - --Check for existing ProgramOfStudy row - IF NOT EXISTS ( - SELECT * + --Get existing ProgramOfStudyId + DECLARE @ProgramOfStudyId INT = ( + SELECT ProgramOfStudyId FROM ProgramOfStudy WHERE Program = @ProgramId AND Degree = @DegreeId AND Curriculum = @CurriculumId - ) + ); + + --If ProgramOfStudyId is null, insert it + IF @ProgramOfStudyId IS NULL BEGIN --Optionally check against DEGREQ IF @DegReqMinYear IS NOT NULL @@ -135,6 +141,28 @@ BEGIN @ProgramId ,@DegreeId ,@CurriculumId + ); + + --Get the newly-inserted ProgramOfStudyId + SET @ProgramOfStudyId = SCOPE_IDENTITY(); + END + + --Check for existing ApplicationProgramSetting row + IF NOT EXISTS ( + SELECT * + FROM ApplicationProgramSetting + WHERE ApplicationFormSettingId = @AppFormSettingId + AND ProgramOfStudyId = @ProgramOfStudyId ) + BEGIN + --Insert new ProgramOfStudyId + INSERT INTO ApplicationProgramSetting ( + ApplicationFormSettingId + ,ProgramOfStudyId + ) + VALUES ( + @AppFormSettingId + ,@ProgramOfStudyId + ); END END diff --git a/Sample FA Status Prompts.xlsx b/Sample FA Status Prompts.xlsx index 0641a6f..7a826a2 100644 Binary files a/Sample FA Status Prompts.xlsx and b/Sample FA Status Prompts.xlsx differ diff --git a/Tools/Create Table PowerSlate_AppStatus_Log.sql b/Tools/Create Table PowerSlate_AppStatus_Log.sql deleted file mode 100644 index 10c3aec..0000000 --- a/Tools/Create Table PowerSlate_AppStatus_Log.sql +++ /dev/null @@ -1,33 +0,0 @@ -USE [PowerCampusMapper] -GO - -/****** Object: Table [dbo].[PowerSlate_AppStatus_Log_test] Script Date: 2/18/2021 3:50:29 PM ******/ -SET ANSI_NULLS ON -GO - -SET QUOTED_IDENTIFIER ON -GO - -CREATE TABLE [dbo].[PowerSlate_AppStatus_Log]( - [ApplicationNumber] [uniqueidentifier] NULL, - [ProspectId] [uniqueidentifier] NULL, - [FirstName] [nvarchar](50) NULL, - [LastName] [nvarchar](50) NULL, - [ComputedStatus] [nvarchar](50) NULL, - [Notes] [nvarchar](max) NULL, - [RecruiterApplicationStatus] [int] NULL, - [ApplicationStatus] [int] NULL, - [PEOPLE_CODE_ID] [nvarchar](10) NULL, - [UpdateTime] [datetime2](7) NULL, - [ID] [int] IDENTITY(1,1) NOT NULL, - [Ref] [nvarchar](16) NULL, -PRIMARY KEY CLUSTERED -( - [ID] ASC -)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] -) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] -GO - -ALTER TABLE [dbo].[PowerSlate_AppStatus_Log] ADD CONSTRAINT [PowerSlate_AppStatus_Log_UpdateTime] DEFAULT (getdate()) FOR [UpdateTime] -GO - diff --git a/Tools/FA Docs - Extract List.sql b/Tools/FA Docs - Extract List.sql new file mode 100644 index 0000000..63ea72b --- /dev/null +++ b/Tools/FA Docs - Extract List.sql @@ -0,0 +1,17 @@ +USE Pfaids + +SELECT '[''' + cast(doc_token AS VARCHAR(50)) + ''',''' + replace(doc_name, '''', '\''') + ''',''' + cast(award_year_token AS NVARCHAR(4)) + ''',''' + iif(use_hyperlink = 1, hyperlink_url, '') + '''],' AS [js_array] +FROM docs +WHERE 1 = 1 + AND award_year_token IN ( + 2023 + ,2024 + ) +--AND doc_token IN ( +-- SELECT doc_token +-- FROM [student_required_documents] srd +-- INNER JOIN stu_award_year sar +-- ON sar.stu_award_year_token = srd.stu_award_year_token +-- WHERE award_year_token = 2023 +-- ) +ORDER BY doc_token diff --git a/Tools/FA Docs - Insert Checklists.js b/Tools/FA Docs - Insert Checklists.js new file mode 100644 index 0000000..d9e6f04 --- /dev/null +++ b/Tools/FA Docs - Insert Checklists.js @@ -0,0 +1,60 @@ +function insertChecklist(docs, status_xml) { + docs.forEach(function (doc) { + values = { + "active": "1", + "folder_type": "lookup.checklist", + "folder_level": "0", + "folder_0": "", + "scope": "", + "group": doc[2], + "section": "Financial Aid", + "subject": doc[1], + "href": doc[3], + "key": doc[0], + "order": "", + "material": "", + "material2": "", + "material3": "", + "material4": "", + "material5": "", + "rank": "", + "test": "", + "test2": "", + "test3": "", + "form_fulfillment": "", + "sql": "", + "xml": status_xml, + "internal": "0", + "optional": "0", + "optional_internal": "0", + "right": "", + "right_update": "", + "export": "", + "cmd": "update" + + } + $.ajax({ + url: "/manage/database/admin?cmd=edit&id=lookup.checklist", + type: "POST", + data: values + }).done(function () { + console.log('Successfully inserted ' + doc[0]); + }) + .fail(function () { + console.log('Failed to insert ' + doc[0]); + return; + }); + + }); +} + +// Standard PF doc statuses and suggested mappings +status_xml = '

statusReceivedWaivedWaivedNot ReviewedApprovedIncompleteNot ReceivedNot Signed

' + +// Array of docs: key, subject, group, url +// Replace with doc list from Tools\Get FA Docs List.sql +docs = [ + ['1234', '2021 Student Signed Tax Return', '2023', 'https://www.irs.gov/individuals/get-transcript'], +] + +// insertChecklist(docs, status_xml); diff --git a/Tools/GRANT EXEC.sql b/Tools/GRANT EXEC.sql index 54472ef..4903c0e 100644 --- a/Tools/GRANT EXEC.sql +++ b/Tools/GRANT EXEC.sql @@ -27,6 +27,3 @@ GRANT EXEC ON [custom].[PS_selPFAwardsXML] to [$(service_user)] GRANT EXEC ON [custom].[PS_selAcademicCalendar] to [$(service_user)] GRANT EXEC ON [custom].[PS_updScholarships] to [$(service_user)] GRANT EXEC ON [custom].[PS_updAssociation] to [$(service_user)] - -USE [PowerCampusMapper] -GRANT INSERT ON PowerSlate_AppStatus_Log TO [$(service_user)] diff --git a/Tools/Mapper Generate Language XML.sql b/Tools/Mapper Generate Language XML.sql new file mode 100644 index 0000000..e5af470 --- /dev/null +++ b/Tools/Mapper Generate Language XML.sql @@ -0,0 +1,8 @@ +USE Campus6 + +SELECT LONG_DESC + ,CODE_VALUE_KEY + ,'' [xml] +FROM CODE_LANGUAGE +WHERE 1 = 1 + AND [STATUS] = 'A' diff --git a/Tools/Mapper Generate Religion XML.sql b/Tools/Mapper Generate Religion XML.sql new file mode 100644 index 0000000..bce849f --- /dev/null +++ b/Tools/Mapper Generate Religion XML.sql @@ -0,0 +1,8 @@ +USE Campus6 + +SELECT LONG_DESC + ,CODE_VALUE_KEY + ,'' [xml] +FROM CODE_RELIGION +WHERE 1 = 1 + AND [STATUS] = 'A' diff --git a/Tools/Populate RecruiterApplication and Application for old apps.sql b/Tools/Populate RecruiterApplication and Application for old apps.sql index 02d6dc6..b733e73 100644 --- a/Tools/Populate RecruiterApplication and Application for old apps.sql +++ b/Tools/Populate RecruiterApplication and Application for old apps.sql @@ -1,10 +1,15 @@ USE PowerCampusMapper +DECLARE @ApplicationFormSettingId INT = 1 + -- -- Tool for populating RecruiterApplication and Application with just enough data to allow -- syncing via PowerSlate as if the applications had been inserted organically via the API. --- I.e. sync your old apps that were manually typed into PowerCampus before you implemented PowerSlate. +-- I.e. sync your old apps that were already in PowerCampus before you implemented PowerSlate. +-- +-- Recommend using string_split()'s enable_ordinal parameter when available (SQL Server 2022+) -- +-- Exclude apps without APPLICATION_FLAG = Y SELECT DISTINCT aid INTO #Exclusions FROM PowerCampusMapper.dbo.Slate_Apps @@ -18,6 +23,7 @@ WHERE PEOPLE_CODE_ID IN ( WHERE APPLICATION_FLAG = 'Y' ) +--Exclude apps with invalid PCID's INSERT INTO #Exclusions SELECT DISTINCT aid FROM PowerCampusMapper.dbo.Slate_Apps @@ -31,8 +37,35 @@ SELECT DISTINCT aid FROM PowerCampusMapper.dbo.Slate_Apps WHERE PEOPLE_CODE_ID IS NULL +--Exclude apps within invalid SessionPeriodId +INSERT INTO #Exclusions +SELECT DISTINCT aid +FROM PowerCampusMapper.dbo.Slate_Apps +WHERE NOT EXISTS ( + SELECT SessionPeriodId + FROM Campus6.dbo.ACADEMICCALENDAR + WHERE ACADEMIC_YEAR = ( + SELECT value + FROM string_split(yearterm, '/') + ORDER BY @@rowcount offset 0 rows FETCH NEXT 1 rows ONLY + ) + AND ACADEMIC_TERM = ( + SELECT value + FROM string_split(yearterm, '/') + ORDER BY @@rowcount offset 1 rows FETCH NEXT 1 rows ONLY + ) + AND ACADEMIC_SESSION = ( + SELECT value + FROM string_split(yearterm, '/') + ORDER BY @@rowcount offset 2 rows FETCH NEXT 1 rows ONLY + ) + ) + PRINT '#Exclusions table built.' +SELECT * +FROM #Exclusions + BEGIN TRAN INSERT INTO [Campus6].[dbo].[Application] ( @@ -49,23 +82,23 @@ INSERT INTO [Campus6].[dbo].[Application] ( ) SELECT getdate() [CreateDatetime] ,2 [Status] - ,[Campus6].[dbo].fngetpersonid(PEOPLE_CODE_ID) [PersonId] + ,P.PersonId [PersonId] ,FirstName ,LastName ,( - SELECT sessionperiodid + SELECT SessionPeriodId FROM Campus6.dbo.ACADEMICCALENDAR - WHERE academic_year = ( + WHERE ACADEMIC_YEAR = ( SELECT value FROM string_split(yearterm, '/') ORDER BY @@rowcount offset 0 rows FETCH NEXT 1 rows ONLY ) - AND academic_term = ( + AND ACADEMIC_TERM = ( SELECT value FROM string_split(yearterm, '/') ORDER BY @@rowcount offset 1 rows FETCH NEXT 1 rows ONLY ) - AND academic_session = ( + AND ACADEMIC_SESSION = ( SELECT value FROM string_split(yearterm, '/') ORDER BY @@rowcount offset 2 rows FETCH NEXT 1 rows ONLY @@ -73,21 +106,27 @@ SELECT getdate() [CreateDatetime] ) [SessionPeriodId] ,0 [FoodPlanInterest] ,0 [DormPlanInterest] - ,1 [ApplicationFormSettingId] + ,@ApplicationFormSettingId [ApplicationFormSettingId] ,aid [OtherSource] -FROM PowerCampusMapper.dbo.Slate_Apps -WHERE aid NOT IN ( - SELECT aid - FROM #Exclusions +FROM PowerCampusMapper.dbo.Slate_Apps SA +LEFT JOIN Campus6.dbo.PEOPLE P + ON P.PEOPLE_CODE_ID = SA.PEOPLE_CODE_ID +WHERE 1 = 1 + AND NOT EXISTS ( + SELECT E.aid + FROM #Exclusions E + WHERE E.aid = SA.aid ) - AND aid NOT IN ( - SELECT applicationnumber + AND NOT EXISTS ( + SELECT ApplicationNumber FROM [Campus6].[dbo].[RecruiterApplication] WHERE ApplicationId IS NOT NULL + AND ApplicationNumber = SA.aid ) - AND aid NOT IN ( - SELECT othersource + AND NOT EXISTS ( + SELECT * FROM [Campus6].[dbo].[Application] + WHERE OtherSource = SA.aid ) PRINT 'Insert into [Application] done.' @@ -105,22 +144,20 @@ INSERT INTO [Campus6].[dbo].[RecruiterApplication] ( SELECT aid ,'{}' ,'' - ,( - SELECT applicationid - FROM [Campus6].[dbo].[Application] - WHERE othersource = aid - ) + ,app.applicationid ,getdate() ,getdate() ,0 ,pid -FROM PowerCampusMapper.dbo.Slate_Apps +FROM PowerCampusMapper.dbo.Slate_Apps SA +INNER JOIN [Campus6].[dbo].[Application] APP + ON app.othersource = sa.aid WHERE aid NOT IN ( SELECT aid FROM #exclusions ) AND aid NOT IN ( - SELECT applicationnumber + SELECT ApplicationNumber FROM [Campus6].[dbo].[RecruiterApplication] ) diff --git a/Tools/Prune log table.sql b/Tools/Prune log table.sql deleted file mode 100644 index 49147f6..0000000 --- a/Tools/Prune log table.sql +++ /dev/null @@ -1,20 +0,0 @@ -USE powercampusmapper; - -WITH RankedIDs_CTE -AS ( - SELECT ID - ,RANK() OVER ( - PARTITION BY ApplicationNumber ORDER BY ID DESC - ) [RankDesc] - ,NULL AS [RankAsc] - ,ApplicationNumber - FROM [PowerSlate_AppStatus_Log_test] - ) -DELETE TOP (9000) -FROM RankedIDs_CTE -WHERE [RankDesc] >= 6 - AND ID <> ( - SELECT MIN(ID) - FROM [PowerSlate_AppStatus_Log_test] L2 - WHERE L2.ApplicationNumber = RankedIDs_CTE.ApplicationNumber - ); diff --git a/Tools/Select Most Recent Status.sql b/Tools/Select Most Recent Status.sql deleted file mode 100644 index 3f1765a..0000000 --- a/Tools/Select Most Recent Status.sql +++ /dev/null @@ -1,28 +0,0 @@ -USE [your_supplementary_database] - -SELECT Ref - ,ApplicationNumber - ,ProspectId - ,FirstName - ,LastName - ,ComputedStatus - ,Notes - ,RecruiterApplicationStatus - ,ApplicationStatus - ,PEOPLE_CODE_ID - ,UpdateTime -FROM - (SELECT Ref - ,ApplicationNumber - ,ProspectId - ,FirstName - ,LastName - ,ComputedStatus - ,Notes - ,RecruiterApplicationStatus - ,ApplicationStatus - ,PEOPLE_CODE_ID - ,UpdateTime - ,RANK() OVER (PARTITION BY ApplicationNumber ORDER BY ID DESC) N - FROM SlaPowInt_AppStatus_Log) E -WHERE N = 1 diff --git a/config_messages.json b/config_messages.json new file mode 100644 index 0000000..fb57f94 --- /dev/null +++ b/config_messages.json @@ -0,0 +1,17 @@ +{ + "error": { + "no_apps": "

No applications found. Perhaps the application(s) are not submitted or are missing required fields?

", + "no_phones": "Application must have at least one phone number.", + "academic_row_not_found": "Record not found by Year/Term/Session/Program/Degree/Curriculum.", + "invalid_college_attend": "College Attend is set to {} in PowerCampus, which is not valid for applicants.", + "api_missing_database": "The PowerCampus Web API is not functioning properly. You may need to remove and reinstall the application.", + "api_token_format": "PowerCampus Web API token should start with 'Bearer '.", + "duplicate_apps": "Person has multiple applications with the same YTS + PCD.", + "missing_yt": "Year/Term/Session is missing from the application.", + "pdc_mapping": "Check Application Form Data Filters, Program of Study, and recruiterMapping.xml if auto-mapping is not enabled. Code values are case-sensitive." + }, + "success": { + "done": "Sync completed with no errors.", + "done_with_errors": "Sync completed, but one or more applications had integration errors." + } +} diff --git a/config_sample.json b/config_sample.json index 25d6397..ee57fa5 100644 --- a/config_sample.json +++ b/config_sample.json @@ -2,8 +2,11 @@ "powercampus": { "api": { "url": "https://webapi.school.edu/", + "auth_method": "[token|basic]", "username": "username", - "password": "astrongpassword" + "password": "astrongpassword", + "token": "Bearer [YOUR TOKEN]", + "app_form_setting_id": 3 }, "autoconfigure_mappings": { "enabled": false, @@ -17,10 +20,6 @@ "note_type": "GENRL" } ], - "logging": { - "enabled": true, - "log_table": "[SomeDatabase].[dbo].[PowerSlate_AppStatus_Log]" - }, "user_defined_fields": [ { "slate_field": "FirstGeneration", @@ -32,7 +31,6 @@ "READ", "blank" ], - "app_form_setting_id": 3, "campus_emailtype": "CAMPUS", "database_string": "Driver={ODBC Driver 17 for SQL Server};Server=servername;Database=campus6;Trusted_Connection=yes;ServerSPN=MSSQLSvc/servername.local.domain.edu;", "mapping_file_location": "\\\\servername\\PowerCampus Mapper\\recruiterMapping.xml", @@ -70,7 +68,8 @@ "advisor", "fa_awards", "fa_status", - "sso_id" + "sso_id", + "academic_guid" ], "url": "https://apply.school.edu/manage/service/import?cmd=load&format=xxxx", "username": "service_user", @@ -99,8 +98,8 @@ }, "teams": { "enabled": false, - "webHookURL" : "[YOUR TEAMS WEBHOOK GOES HERE]", - "title" : "PowerSlate [Production] Alert" + "webHookURL": "[YOUR TEAMS WEBHOOK GOES HERE]", + "title": "PowerSlate [Production] Alert" }, "scheduled_actions": { "enabled": false, @@ -117,7 +116,8 @@ ] }, "fa_checklist": { - "enabled": true, + "enabled": false, + "use_finaidmapping": false, "slate_post": { "url": "https://apply.school.edu/manage/query/run?id=xxxx&h=xxxx&cmd=service&output=json", "username": "username", @@ -125,22 +125,14 @@ } }, "fa_awards": { - "enabled": true + "enabled": false, + "use_finaidmapping": false }, "defaults": { "address_country": null, "phone_country": "US", "phone_type": 1 }, - "msg_strings": { - "error_no_apps": "

No applications found. Perhaps the application(s) are not submitted or are missing required fields?

", - "error_no_phones": "Application must have at least one phone number.", - "error_academic_row_not_found": "Record not found by Year/Term/Session/Program/Degree/Curriculum.", - "error_invalid_college_attend": "College Attend is set to {} in PowerCampus, which is not valid for applicants.", - "error_api_missing_database": "The PowerCampus Web API is not functioning properly. You may need to remove and reinstall the application.", - "sync_done": "Sync completed with no errors.", - "sync_done_not_found": "Sync completed, but one or more applications had integration errors." - }, "http_port": null, "http_ip": null } diff --git a/ps_core.py b/ps_core.py index 26fbae6..26b3172 100644 --- a/ps_core.py +++ b/ps_core.py @@ -15,11 +15,19 @@ # The Settings class should replace the CONFIG global in all new code. class Settings: + class FlatDict: + def __init__(self, contents): + for field in contents: + setattr(self, field, contents[field]) + def __init__(self, config): self.fa_awards = self.FlatDict(config["fa_awards"]) - self.powercampus = self.PowerCampus(config["powercampus"]) + self.fa_checklist = self.FlatDict(config["fa_checklist"]) self.console_verbose = config["console_verbose"] - self.msg_strings = self.FlatDict(config["msg_strings"]) + self.defaults = self.FlatDict(config["defaults"]) + self.PowerCampus = self.PowerCampus(config["powercampus"]) + self.Messages = self.Messages() + self.check_api_token() class PowerCampus: def __init__(self, config): @@ -31,19 +39,26 @@ def __init__(self, config): for d in dicts: setattr(self, d, Settings.FlatDict(config[d])) - class FlatDict: - def __init__(self, contents): - for field in contents: - setattr(self, field, contents[field]) + class Messages: + def __init__(self): + with open("config_messages.json") as file: + messages = json.loads(file.read()) + self.error = Settings.FlatDict(messages["error"]) + self.success = Settings.FlatDict(messages["success"]) + + def check_api_token(self): + if ( + self.PowerCampus.api.auth_method == "token" + and self.PowerCampus.api.token[:7] != "Bearer " + ): + raise ValueError(self.Messages.error.api_token_format) def init(config_path): """Reads config file to global CONFIG dict. Many frequently-used variables are copied to their own globals for convenince.""" global CONFIG global CONFIG_PATH - global FIELDS global RM_MAPPING - global MSG_STRINGS global SETTINGS # New global for Settings class CONFIG_PATH = config_path @@ -52,14 +67,11 @@ def init(config_path): SETTINGS = Settings(CONFIG) RM_MAPPING = ps_powercampus.get_recruiter_mapping( - SETTINGS.powercampus.mapping_file_location + SETTINGS.PowerCampus.mapping_file_location ) - MSG_STRINGS = CONFIG["msg_strings"] # Init PowerCampus API and SQL connections - ps_powercampus.init( - SETTINGS.powercampus, SETTINGS.console_verbose, SETTINGS.msg_strings - ) + ps_powercampus.init(SETTINGS.PowerCampus, SETTINGS.console_verbose) return CONFIG @@ -309,7 +321,7 @@ def main_sync(pid=None): apps = {k["aid"]: k for k in apps} if len(apps) == 0 and pid is not None: # Assuming we're running in interactive (HTTP) mode if pid param exists - raise EOFError(MSG_STRINGS["error_no_apps"]) + raise EOFError(SETTINGS.Messages.error.no_apps) elif len(apps) == 0: # Don't raise an error for scheduled mode return None @@ -317,26 +329,59 @@ def main_sync(pid=None): verbose_print("Clean up app data from Slate (datatypes, supply nulls, etc.)") for k, v in apps.items(): CURRENT_RECORD = k - apps[k] = format_app_generic(v, CONFIG["slate_upload_active"]) + apps[k] = format_app_generic( + v, CONFIG["slate_upload_active"], SETTINGS.Messages + ) - if SETTINGS.powercampus.autoconfigure_mappings.enabled: + # Set error flag if one pid has multiple applications with the same YTS + PCD + duplicates = [] + for k, v in apps.items(): + duplicates.extend( + [ + kk + for kk, vv in apps.items() + if vv["pid"] == v["pid"] + and k != kk # Not self + and vv["Program"] == v["Program"] + and vv["Degree"] == v["Degree"] + # Needed if and when switching from two to three fields for 9.2.3 + and vv["Curriculum"] == v["Curriculum"] + and vv["YearTerm"] == v["YearTerm"] + ] + ) + + for k in duplicates: + apps[k]["error_flag"] = True + apps[k]["error_message"] = SETTINGS.Messages.error.duplicate_apps + + if SETTINGS.PowerCampus.autoconfigure_mappings.enabled: verbose_print("Auto-configure ProgramOfStudy and recruiterMapping.xml") CURRENT_RECORD = None - mfl = SETTINGS.powercampus.mapping_file_location - vd = SETTINGS.powercampus.autoconfigure_mappings.validate_degreq - mdy = SETTINGS.powercampus.autoconfigure_mappings.minimum_degreq_year - dp_list = [ + mfl = SETTINGS.PowerCampus.mapping_file_location + vd = SETTINGS.PowerCampus.autoconfigure_mappings.validate_degreq + mdy = SETTINGS.PowerCampus.autoconfigure_mappings.minimum_degreq_year + afsi = SETTINGS.PowerCampus.api.app_form_setting_id + program_list = [ (apps[app]["Program"], apps[app]["Degree"]) for app in apps if "Degree" in apps[app] ] yt_list = [apps[app]["YearTerm"] for app in apps if "YearTerm" in apps[app]] - if ps_powercampus.autoconfigure_mappings(dp_list, yt_list, vd, mdy, mfl): + if ps_powercampus.autoconfigure_mappings( + program_list, + yt_list, + vd, + mdy, + mfl, + afsi, + ): RM_MAPPING = ps_powercampus.get_recruiter_mapping(mfl) verbose_print("Check each app's status flags/PCID in PowerCampus") for k, v in apps.items(): + if v["error_flag"] == True: + continue CURRENT_RECORD = k status_ra, status_app, status_calc, pcid = ps_powercampus.scan_status(v) apps[k].update( @@ -350,34 +395,47 @@ def main_sync(pid=None): verbose_print("Post new or repost unprocessed applications to PowerCampus API") for k, v in apps.items(): + if v["error_flag"] == True: + continue CURRENT_RECORD = k - if (v["status_ra"] == None) or ( - v["status_ra"] in (1, 2) and v["status_app"] is None + if ( + (v["status_ra"] == None) + or (v["status_ra"] in (1, 2) and v["status_app"] is None) + or (v["status_ra"] == 0 and v["status_app"] == None) # 9.2.3 new bad status ): - pcid = ps_powercampus.post_api( - format_app_api(v, CONFIG["defaults"]), - MSG_STRINGS, - SETTINGS.powercampus.app_form_setting_id, - ) - apps[k]["PEOPLE_CODE_ID"] = pcid - - # Rescan status - status_ra, status_app, status_calc, pcid = ps_powercampus.scan_status(v) - apps[k].update( - { - "status_ra": status_ra, - "status_app": status_app, - "status_calc": status_calc, - } + app, error_flag, error_message = format_app_api( + v, SETTINGS.defaults, SETTINGS.Messages ) - apps[k]["PEOPLE_CODE_ID"] = pcid + if error_flag: + apps[k]["error_flag"] = error_flag + apps[k]["error_message"] = error_message + else: + pcid = ps_powercampus.post_api( + app, SETTINGS.PowerCampus.api, SETTINGS.Messages + ) + apps[k]["PEOPLE_CODE_ID"] = pcid + + # Rescan status + status_ra, status_app, status_calc, pcid = ps_powercampus.scan_status(v) + apps[k].update( + { + "status_ra": status_ra, + "status_app": status_app, + "status_calc": status_calc, + } + ) + apps[k]["PEOPLE_CODE_ID"] = pcid - verbose_print("Get scheduled actions from Slate") if CONFIG["scheduled_actions"]["enabled"] == True: + verbose_print("Get scheduled actions from Slate") CURRENT_RECORD = None # Send list of app GUID's to Slate; get back checklist items actions_list = slate_get_actions( - [k for (k, v) in apps.items() if v["status_calc"] == "Active"] + [ + k + for (k, v) in apps.items() + if v["status_calc"] == "Active" and v["error_flag"] == False + ] ) if CONFIG["scheduled_actions"]["autolearn_action_codes"] == True: @@ -386,17 +444,22 @@ def main_sync(pid=None): verbose_print("Update existing applications in PowerCampus and extract information") edu_sync_results = [] for k, v in apps.items(): + if v["error_flag"] == True: + continue CURRENT_RECORD = k if v["status_calc"] == "Active": # Transform to PowerCampus format - app_pc = format_app_sql(v, RM_MAPPING, SETTINGS.powercampus) + app_pc = format_app_sql(v, RM_MAPPING, SETTINGS.PowerCampus) pcid = app_pc["PEOPLE_CODE_ID"] academic_year = app_pc["ACADEMIC_YEAR"] academic_term = app_pc["ACADEMIC_TERM"] academic_session = app_pc["ACADEMIC_SESSION"] # Single-row updates - if SETTINGS.powercampus.update_academic_key: + if ( + SETTINGS.PowerCampus.update_academic_key + and app_pc["AcademicGUID"] is not None + ): ps_powercampus.update_academic_key(app_pc) ps_powercampus.update_demographics(app_pc) ps_powercampus.update_academic(app_pc) @@ -437,7 +500,7 @@ def main_sync(pid=None): ps_powercampus.update_test_scores(pcid, test) # Update any PowerCampus Notes defined in config - for note in SETTINGS.powercampus.notes: + for note in SETTINGS.PowerCampus.notes: if ( note["slate_field"] in app_pc and len(app_pc[note["slate_field"]]) > 0 @@ -447,7 +510,7 @@ def main_sync(pid=None): ) # Update any PowerCampus User Defined fields defined in config - for udf in SETTINGS.powercampus.user_defined_fields: + for udf in SETTINGS.PowerCampus.user_defined_fields: if udf["slate_field"] in app_pc and len(app_pc[udf["slate_field"]]) > 0: ps_powercampus.update_udf( app_pc, udf["slate_field"], udf["pc_field"] @@ -466,7 +529,7 @@ def main_sync(pid=None): ps_powercampus.update_scholarship( pcid, scholarship, - SETTINGS.powercampus.validate_scholarship_levels, + SETTINGS.PowerCampus.validate_scholarship_levels, ) # Update PowerCampus Associations @@ -487,13 +550,14 @@ def main_sync(pid=None): campus_email, advisor, sso_id, + academic_guid, custom_1, custom_2, custom_3, custom_4, custom_5, ) = ps_powercampus.get_profile( - app_pc, SETTINGS.powercampus.campus_emailtype + app_pc, SETTINGS.PowerCampus.campus_emailtype, SETTINGS.Messages ) apps[k].update( { @@ -507,6 +571,7 @@ def main_sync(pid=None): "campus_email": campus_email, "advisor": advisor, "sso_id": sso_id, + "academic_guid": academic_guid, "custom_1": custom_1, "custom_2": custom_2, "custom_3": custom_3, @@ -525,6 +590,7 @@ def main_sync(pid=None): academic_year, academic_term, academic_session, + SETTINGS.fa_awards.use_finaidmapping, ) apps[k].update({"fa_awards": fa_awards, "fa_status": fa_status}) @@ -543,16 +609,18 @@ def main_sync(pid=None): ) # Collect Financial Aid checklist and upload to Slate - if CONFIG["fa_checklist"]["enabled"] == True: + if SETTINGS.fa_checklist.enabled == True: verbose_print("Collect Financial Aid checklist and upload to Slate") slate_upload_list = [] # slate_upload_fields = {'AppID', 'Code', 'Status', 'Date'} for k, v in apps.items(): CURRENT_RECORD = k + if v["error_flag"] == True: + continue if v["status_calc"] == "Active": # Transform to PowerCampus format - app_pc = format_app_sql(v, RM_MAPPING, SETTINGS.powercampus) + app_pc = format_app_sql(v, RM_MAPPING, SETTINGS.PowerCampus) fa_checklists = ps_powercampus.pf_get_fachecklist( app_pc["PEOPLE_CODE_ID"], @@ -561,6 +629,7 @@ def main_sync(pid=None): app_pc["ACADEMIC_YEAR"], app_pc["ACADEMIC_TERM"], app_pc["ACADEMIC_SESSION"], + SETTINGS.fa_checklist.use_finaidmapping, ) slate_upload_list = slate_upload_list + fa_checklists @@ -568,10 +637,10 @@ def main_sync(pid=None): slate_post_fa_checklist(slate_upload_list) # Warn if any apps returned an error flag from ps_powercampus.get_profile() - if sync_errors == True: - output_msg = MSG_STRINGS["sync_done_not_found"] + if sync_errors == True or [k for k in apps if apps[k]["error_flag"] == True]: + output_msg = SETTINGS.Messages.success.done_with_errors else: - output_msg = MSG_STRINGS["sync_done"] + output_msg = SETTINGS.Messages.success.done verbose_print(output_msg) return output_msg diff --git a/ps_format.py b/ps_format.py index 463822f..90723f3 100644 --- a/ps_format.py +++ b/ps_format.py @@ -31,7 +31,9 @@ def __init__(self, row): self.cleared_date = row["ClearedDate"] else: self.cleared_date = None - if "comments" in row: + if "Comments" in row: + self.comments = format_blank_to_null(row["Comments"]) + elif "comments" in row: self.comments = format_blank_to_null(row["comments"]) else: self.comments = None @@ -145,10 +147,12 @@ def format_str_digits(s): return s.translate(non_digits) -def format_app_generic(app, cfg_fields): +def format_app_generic(app, cfg_fields, Messages): """Supply missing fields and correct datatypes. Returns a flat dict.""" mapped = format_blank_to_null(app) + mapped["error_flag"] = False + mapped["error_message"] = None fields_null = [k for (k, v) in ps_models.fields.items() if v["supply_null"] == True] fields_bool = [k for (k, v) in ps_models.fields.items() if v["type"] == bool] @@ -160,7 +164,9 @@ def format_app_generic(app, cfg_fields): fields_int.extend(["compare_" + field for field in cfg_fields["fields_int"]]) # Copy nullable strings from input to output, then fill in nulls - mapped.update({k: v for (k, v) in app.items() if k in fields_null}) + mapped.update( + {k: v for (k, v) in app.items() if k in fields_null and k not in mapped} + ) mapped.update({k: None for k in fields_null if k not in app}) # Convert integers and booleans @@ -175,13 +181,25 @@ def format_app_generic(app, cfg_fields): else: mapped["GovernmentDateOfEntry"] = app["GovernmentDateOfEntry"] + # Academic program + # API 9.2.3 still requires two fields for Program and Degree, even though the Swagger schema contains three fields. + # Done here instead of in format_app_api() because format_app_sql() also needs these fields standardized. + if "Curriculum" in app: + mapped["Program"] = app["Program"] + mapped["Degree"] = app["Degree"] + "/" + app["Curriculum"] + mapped["Curriculum"] = None + else: + mapped["Program"] = app["Program"] + mapped["Degree"] = app["Degree"] + mapped["Curriculum"] = None + # Pass through all other fields mapped.update({k: v for (k, v) in app.items() if k not in mapped}) return mapped -def format_app_api(app, cfg_defaults): +def format_app_api(app, cfg_defaults, Messages): """Remap application to Recruiter/Web API format. Keyword arguments: @@ -189,6 +207,13 @@ def format_app_api(app, cfg_defaults): """ mapped = {} + error_flag = False + error_message = None + + # Error checks + if "YearTerm" not in app: + error_message = Messages.error.missing_yt + error_flag = True # Pass through fields fields_verbatim = [ @@ -206,7 +231,7 @@ def format_app_api(app, cfg_defaults): { k[8:]: v for (k, v) in app.items() - if k[0:7] == "Address" and int(k[7:8]) - 1 == i + if k[0:7] == "Address" and int(k[7:8]) - 1 == i and v is not None } for i in range(10) ] @@ -232,8 +257,8 @@ def format_app_api(app, cfg_defaults): k["StateProvince"] = None if "PostalCode" not in k: k["PostalCode"] = None - if "County" not in k: - k["County"] = cfg_defaults["address_country"] + if "Country" not in k: + k["Country"] = cfg_defaults.address_country if len([k for k in app if k[:5] == "Phone"]) > 0: has_phones = True @@ -261,36 +286,39 @@ def format_app_api(app, cfg_defaults): item["Number"] = format_phone_number(item["Number"]) if "Type" not in item: - item["Type"] = cfg_defaults["phone_type"] + item["Type"] = cfg_defaults.phone_type else: item["Type"] = int(item["Type"]) if "Country" not in item: - item["Country"] = cfg_defaults["phone_country"] + item["Country"] = cfg_defaults.phone_country else: # PowerCampus WebAPI requires Type -1 instead of a blank or null when not submitting any phones. mapped["PhoneNumbers"] = [{"Type": -1, "Country": None, "Number": None}] - # Veteran has funny logic, and API 8.8.3 is broken (passing in 1 will write 2 into [Application].[VeteranStatus]). - # Impact is low because custom SQL routines will fix Veteran field once person has passed Handle Applications. + # Suspect Veteran logic was updated in API 9.2.x + # Changed how this is handled to be less confusing. if app["Veteran"] is None: - mapped["Veteran"] = 0 + mapped["Veteran"] = None mapped["VeteranStatus"] = False else: - mapped["Veteran"] = int(app["Veteran"]) + mapped["Veteran"] = app["Veteran"] mapped["VeteranStatus"] = True - # Academic program mapped["Programs"] = [ - {"Program": app["Program"], "Degree": app["Degree"], "Curriculum": None} + { + "Program": app["Program"], + "Degree": app["Degree"], + "Curriculum": None, + } ] # GUID's mapped["ApplicationNumber"] = app["aid"] mapped["ProspectId"] = app["pid"] - return mapped + return mapped, error_flag, error_message def format_app_sql(app, mapping, config): @@ -298,6 +326,8 @@ def format_app_sql(app, mapping, config): Keyword arguments: app -- an application dict + mapping -- a mapping dict derived from recruiterMapping.xml + config -- Settings class object """ mapped = {} @@ -332,20 +362,27 @@ def format_app_sql(app, mapping, config): mapped["ACADEMIC_SESSION"] = mapping["AcademicTerm"]["PCSessionCodeValue"][ app["YearTerm"] ] - # Todo: Fix inconsistency of 1-field vs 2-field mappings + mapped["PROGRAM"] = mapping["AcademicLevel"][app["Program"]] mapped["DEGREE"] = mapping["AcademicProgram"]["PCDegreeCodeValue"][app["Degree"]] mapped["CURRICULUM"] = mapping["AcademicProgram"]["PCCurriculumCodeValue"][ app["Degree"] ] - if app["CitizenshipStatus"] is not None: + if app["PrimaryCitizenship"] is not None: mapped["PRIMARYCITIZENSHIP"] = mapping["CitizenshipStatus"][ - app["CitizenshipStatus"] + app["PrimaryCitizenship"] ] else: mapped["PRIMARYCITIZENSHIP"] = None + if app["SecondaryCitizenship"] is not None: + mapped["SECONDARYCITIZENSHIP"] = mapping["CitizenshipStatus"][ + app["SecondaryCitizenship"] + ] + else: + mapped["SECONDARYCITIZENSHIP"] = None + if app["CollegeAttendStatus"] is not None: mapped["COLLEGE_ATTEND"] = mapping["CollegeAttend"][app["CollegeAttendStatus"]] else: @@ -356,18 +393,6 @@ def format_app_sql(app, mapping, config): else: mapped["VISA"] = None - if app["Veteran"] is not None: - mapped["VETERAN"] = mapping["Veteran"][str(app["Veteran"])] - else: - mapped["VETERAN"] = None - - if app["SecondaryCitizenship"] is not None: - mapped["SECONDARYCITIZENSHIP"] = mapping["CitizenshipStatus"][ - app["SecondaryCitizenship"] - ] - else: - mapped["SECONDARYCITIZENSHIP"] = None - if app["MaritalStatus"] is not None: mapped["MARITALSTATUS"] = mapping["MaritalStatus"][app["MaritalStatus"]] else: diff --git a/ps_models.py b/ps_models.py index 33c848a..edbc779 100644 --- a/ps_models.py +++ b/ps_models.py @@ -41,12 +41,6 @@ "supply_null": False, "type": str, }, - "CitizenshipStatus": { - "api_verbatim": True, - "sql_verbatim": False, - "supply_null": True, - "type": str, - }, "CollegeAttendStatus": { "api_verbatim": True, "sql_verbatim": False, @@ -83,6 +77,12 @@ "supply_null": True, "type": str, }, + "College": { + "api_verbatim": False, + "sql_verbatim": True, + "supply_null": True, + "type": str, + }, "Department": { "api_verbatim": False, "sql_verbatim": True, @@ -227,6 +227,18 @@ "supply_null": True, "type": str, }, + "SetProgramStartDate": { + "api_verbatim": False, + "sql_verbatim": True, + "supply_null": True, + "type": bool, + }, + "SecondaryCitizenship": { + "api_verbatim": True, + "sql_verbatim": False, + "supply_null": True, + "type": str, + }, "PrimaryLanguage": { "api_verbatim": True, "sql_verbatim": False, @@ -281,12 +293,6 @@ "supply_null": False, "type": int, }, - "SecondaryCitizenship": { - "api_verbatim": True, - "sql_verbatim": False, - "supply_null": True, - "type": str, - }, "Status": { "api_verbatim": True, "sql_verbatim": False, @@ -301,7 +307,7 @@ }, "Veteran": { "api_verbatim": False, - "sql_verbatim": False, + "sql_verbatim": True, "supply_null": True, "type": str, }, @@ -329,6 +335,12 @@ "supply_null": False, "type": str, }, + "AcademicGUID": { + "api_verbatim": False, + "sql_verbatim": True, + "supply_null": True, + "type": str, + }, } arrays = { diff --git a/ps_powercampus.py b/ps_powercampus.py index 0817e31..4e4bf26 100644 --- a/ps_powercampus.py +++ b/ps_powercampus.py @@ -5,36 +5,28 @@ import ps_models -def init(config, verbose, msg_strings): - global PC_API_URL - global PC_API_CRED +def init(config, verbose): global CNXN global CURSOR global CONFIG global VERBOSE - global MSG_STRINGS CONFIG = config VERBOSE = verbose - MSG_STRINGS = msg_strings - - # PowerCampus Web API connection - PC_API_URL = config.api.url - PC_API_CRED = (config.api.username, config.api.password) # Microsoft SQL Server connection. CNXN = pyodbc.connect(config.database_string) CURSOR = CNXN.cursor() # Print a test of connections - r = requests.get(PC_API_URL + "api/version", auth=PC_API_CRED) + r = requests.get(config.api.url + "api/version") verbose_print("PowerCampus API Status: " + str(r.status_code)) verbose_print(r.text) r.raise_for_status() verbose_print("Database:" + CNXN.getinfo(pyodbc.SQL_DATABASE_NAME)) # Enable ApplicationFormSetting's ProcessAutomatically in case program exited abnormally last time with setting toggled off. - update_app_form_autoprocess(config.app_form_setting_id, True) + update_app_form_autoprocess(config.api.app_form_setting_id, True) def de_init(): @@ -56,7 +48,12 @@ def verbose_print(x): def autoconfigure_mappings( - dp_list, yt_list, validate_degreq, minimum_degreq_year, mapping_file_location + program_list, + yt_list, + validate_degreq, + minimum_degreq_year, + mapping_file_location, + app_form_setting_id, ): """ Automatically insert new Program/Degree/Curriculum combinations into ProgramOfStudy and recruiterMapping.xml @@ -65,20 +62,22 @@ def autoconfigure_mappings( and that YearTerm values are like YEAR/TERM/SESSION. Keyword aguments: - dp_list -- a list of tuples like [('PROGRAM','DEGREE/CURRICULUM'), (...)] + program_list -- list of tuples like [('PROGRAM','DEGREE/CURRICULUM'), (...)] + yt_list -- list of strings like ['YEAR/TERM/SESSION', ...] validate_degreq -- bool. If True, check against DEGREQ for sanity using minimum_degreq_year. minimum_degreq_year -- str + mapping_file_location -- str. Path to recruiterMapping.xml Returns True if XML mapping changed. """ - dp_set = set(dp_list) + program_set = set(program_list) yt_set = set(yt_list) if validate_degreq == False: minimum_degreq_year = None # Create set of tuples like {('PROGRAM','DEGREE', 'CURRICULUM'), (...)} pdc_set = set() - for dp in dp_set: + for dp in program_set: pdc = [dp[0]] for dc in dp[1].split("/"): pdc.append(dc) @@ -111,11 +110,12 @@ def autoconfigure_mappings( # Update ProgramOfStudy table; optionally validate against DEGREQ table for pdc in pdc_set: CURSOR.execute( - "execute [custom].[PS_updProgramOfStudy] ?, ?, ?, ?", + "execute [custom].[PS_updProgramOfStudy] ?, ?, ?, ?, ?", pdc[0], pdc[1], pdc[2], minimum_degreq_year, + app_form_setting_id, ) CNXN.commit() @@ -255,7 +255,7 @@ def get_recruiter_mapping(mapping_file_location): return rm_mapping -def post_api(x, cfg_strings, app_form_setting_id): +def post_api(app, config, Messages): """Post an application to PowerCampus. Return PEOPLE_CODE_ID if application was automatically accepted or None for all other conditions. @@ -263,17 +263,26 @@ def post_api(x, cfg_strings, app_form_setting_id): x -- an application dict """ + creds = None + headers = None + if config.auth_method == "basic": + creds = (config.username, config.password) + elif config.auth_method == "token": + headers = {"Authorization": config.token} + # Check for duplicate person. If found, temporarily toggle auto-process off. dup_found = False - CURSOR.execute("EXEC [custom].[PS_selPersonDuplicate] ?", x["GovernmentId"]) + CURSOR.execute("EXEC [custom].[PS_selPersonDuplicate] ?", app["GovernmentId"]) row = CURSOR.fetchone() dup_found = row.DuplicateFound if dup_found: - update_app_form_autoprocess(app_form_setting_id, False) + update_app_form_autoprocess(config.app_form_setting_id, False) # Expose error text response from API, replace useless error message(s). try: - r = requests.post(PC_API_URL + "api/applications", json=x, auth=PC_API_CRED) + r = requests.post( + config.url + "api/applications", json=app, auth=creds, headers=headers + ) r.raise_for_status() # The API returns 202 for mapping errors. Technically 202 is appropriate, but it should bubble up to the user. if r.status_code == 202: @@ -283,36 +292,42 @@ def post_api(x, cfg_strings, app_form_setting_id): rtext = r.text.replace("\r\n", "\n") if dup_found: - update_app_form_autoprocess(app_form_setting_id, True) + update_app_form_autoprocess(config.app_form_setting_id, True) if ( "BadRequest Object reference not set to an instance of an object." in rtext and "ApplicationsController.cs:line 183" in rtext ): - raise ValueError(cfg_strings["error_no_phones"], rtext, e) + raise ValueError(Messages.error.no_phones, rtext, e) elif ( "BadRequest Activation error occured while trying to get instance of type Database, key" in rtext and "ServiceLocatorImplBase.cs:line 53" in rtext ): - raise ValueError(cfg_strings["error_api_missing_database"], rtext, e) - elif r.status_code == 202 or r.status_code == 400: - raise ValueError(rtext) - else: + raise ValueError(Messages.error.api_missing_database, rtext, e) + elif "/ was not found in Mapping file." in rtext: + raise ValueError(rtext, Messages.error.pdc_mapping) + elif ( + "was created succesfully in PowerCampus" not in rtext + and "was created successfully in PowerCampus" not in rtext + ): raise requests.HTTPError(rtext) if dup_found: - update_app_form_autoprocess(app_form_setting_id, True) + update_app_form_autoprocess(config.app_form_setting_id, True) - if r.text[-25:-12] == "New People Id": + if "New People Id" in r.text: + # Example 9.2.3 response: "The application 13 was created successfully in PowerCampus. New People Id 000123456." try: - people_code = r.text[-11:-2] - # Error check. After slice because leading zeros need preserved. + people_code = r.text.split("New People Id ")[1].split(".")[0] int(people_code) PEOPLE_CODE_ID = "P" + people_code return PEOPLE_CODE_ID except: - return None + raise ValueError( + "Unable to parse PEOPLE_ID from API response.", + r.text, + ) else: return None @@ -357,35 +372,10 @@ def scan_status(x): else: computed_status = "Unrecognized Status: " + str(row.ra_status) - if CONFIG.logging.enabled: - # Write errors to external database for end-user presentation via SSRS. - CURSOR.execute( - "INSERT INTO" - + CONFIG.logging.log_table - + """ - ([Ref],[ApplicationNumber],[ProspectId],[FirstName],[LastName], - [ComputedStatus],[Notes],[RecruiterApplicationStatus],[ApplicationStatus],[PEOPLE_CODE_ID]) - VALUES - (?,?,?,?,?,?,?,?,?,?)""", - [ - x["Ref"], - x["aid"], - x["pid"], - x["FirstName"], - x["LastName"], - computed_status, - row.ra_errormessage, - row.ra_status, - row.apl_status, - pcid, - ], - ) - CNXN.commit() - return ra_status, apl_status, computed_status, pcid -def get_profile(app, campus_email_type): +def get_profile(app, campus_email_type, Messages): """Fetch ACADEMIC row data and email address from PowerCampus. Returns: @@ -399,7 +389,7 @@ def get_profile(app, campus_email_type): """ error_flag = True - error_message = MSG_STRINGS.error_academic_row_not_found + error_message = None registered = False reg_date = None readmit = False @@ -408,6 +398,7 @@ def get_profile(app, campus_email_type): campus_email = None advisor = None sso_id = None + academic_guid = None custom_1 = None custom_2 = None custom_3 = None @@ -415,7 +406,7 @@ def get_profile(app, campus_email_type): custom_5 = None CURSOR.execute( - "EXEC [custom].[PS_selProfile] ?,?,?,?,?,?,?,?", + "EXEC [custom].[PS_selProfile] ?, ?, ?, ?, ?, ?, ?, ?, ?", app["PEOPLE_CODE_ID"], app["ACADEMIC_YEAR"], app["ACADEMIC_TERM"], @@ -424,44 +415,49 @@ def get_profile(app, campus_email_type): app["DEGREE"], app["CURRICULUM"], campus_email_type, + app["AcademicGUID"], ) row = CURSOR.fetchone() - if row is not None: - error_flag = False - - if row.Registered == "Y": - registered = True - reg_date = str(row.REG_VAL_DATE) - credits = str(row.CREDITS) - - campus_email = row.CampusEmail - advisor = row.AdvisorUsername - sso_id = row.Username - custom_1 = row.custom_1 - custom_2 = row.custom_2 - custom_3 = row.custom_3 - custom_4 = row.custom_4 - custom_5 = row.custom_5 - - # College Attend and Readmits - college_attend = row.COLLEGE_ATTEND - if college_attend == CONFIG.readmit_code: - readmit = True - elif college_attend == "" or college_attend is None: - college_attend = "blank" - - if college_attend not in CONFIG.valid_college_attend: - error_flag = True - error_message = MSG_STRINGS.error_invalid_college_attend.format( - college_attend - ) - - if row.Withdrawn == "Y": - withdrawn = True + if row is None: + # ACADEMIC row not found by YTSPDC or GUID. + error_message = Messages.error.academic_row_not_found + else: + if row.ErrorFlag == 1: + # ACADEMIC row found by GUID but YTSPDC does not match. + error_message = row.ErrorMessage + else: + error_flag = False + if row.Registered == "Y": + registered = True + reg_date = str(row.REG_VAL_DATE) + credits = str(row.CREDITS) + + campus_email = row.CampusEmail + advisor = row.AdvisorUsername + sso_id = row.Username + academic_guid = row.Guid + custom_1 = row.custom_1 + custom_2 = row.custom_2 + custom_3 = row.custom_3 + custom_4 = row.custom_4 + custom_5 = row.custom_5 + + # College Attend and Readmits + college_attend = row.COLLEGE_ATTEND + if college_attend == CONFIG.readmit_code: + readmit = True + elif college_attend == "" or college_attend is None: + college_attend = "blank" + + if college_attend not in CONFIG.valid_college_attend: + error_flag = True + error_message = Messages.error.invalid_college_attend.format( + college_attend + ) - if not error_flag: - error_message = None + if row.Withdrawn == "Y": + withdrawn = True return ( error_flag, @@ -474,6 +470,7 @@ def get_profile(app, campus_email_type): campus_email, advisor, sso_id, + academic_guid, custom_1, custom_2, custom_3, @@ -492,7 +489,7 @@ def update_demographics(app): app["DemographicsEthnicity"], app["MARITALSTATUS"], app["Religion"], - app["VETERAN"], + app["Veteran"], app["PRIMARYCITIZENSHIP"], app["SECONDARYCITIZENSHIP"], app["VISA"], @@ -515,7 +512,7 @@ def update_academic(app): If ACADEMIC_FLAG isn't yet set to Y, update ACADEMIC.ORG_CODE_ID based on the passed OrganizationId. """ CURSOR.execute( - "exec [custom].[PS_updAcademicAppInfo] ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?", + "exec [custom].[PS_updAcademicAppInfo] ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?", app["PEOPLE_CODE_ID"], app["ACADEMIC_YEAR"], app["ACADEMIC_TERM"], @@ -523,6 +520,7 @@ def update_academic(app): app["PROGRAM"], app["DEGREE"], app["CURRICULUM"], + app["College"], app["Department"], app["Nontraditional"], app["Population"], @@ -537,6 +535,7 @@ def update_academic(app): app["COLLEGE_ATTEND"], app["Extracurricular"], app["CreateDateTime"], + app["SetProgramStartDate"], ) CNXN.commit() @@ -554,7 +553,7 @@ def update_academic_key(app): app["PROGRAM"], app["DEGREE"], app["CURRICULUM"], - app["aid"], + app["AcademicGUID"], ) CNXN.commit() @@ -856,45 +855,48 @@ def update_association(pcid, association): CNXN.commit() -def pf_get_fachecklist(pcid, govid, appid, year, term, session): +def pf_get_fachecklist(pcid, govid, appid, year, term, session, use_finaidmapping): """Return the PowerFAIDS missing docs list for uploading to Financial Aid Checklist.""" checklist = [] CURSOR.execute( - "exec [custom].[PS_selPFChecklist] ?, ?, ?, ?, ?", + "exec [custom].[PS_selPFChecklist] ?, ?, ?, ?, ?, ?", pcid, govid, year, term, session, + use_finaidmapping, ) columns = [column[0] for column in CURSOR.description] - for row in CURSOR.fetchall(): - checklist.append(dict(zip(columns, row))) + if 'Code' in columns: + for row in CURSOR.fetchall(): + checklist.append(dict(zip(columns, row))) - # Pass through the Slate Application ID - for doc in checklist: - doc["AppID"] = appid + # Pass through the Slate Application ID + for doc in checklist: + doc["AppID"] = appid return checklist -def pf_get_awards(pcid, govid, year, term, session): +def pf_get_awards(pcid, govid, year, term, session, use_finaidmapping): """Return the PowerFAIDS awards list as XML and the Tracking Status.""" awards = None tracking_status = None CURSOR.execute( - "exec [custom].[PS_selPFAwardsXML] ?, ?, ?, ?, ?", + "exec [custom].[PS_selPFAwardsXML] ?, ?, ?, ?, ?, ?", pcid, govid, year, term, session, + use_finaidmapping, ) row = CURSOR.fetchone() - if row is not None: + if row[0] is not None: awards = row.XML tracking_status = row.tracking_status diff --git a/sync_http.py b/sync_http.py index ff472df..6c106f4 100644 --- a/sync_http.py +++ b/sync_http.py @@ -17,7 +17,7 @@ def emit_traceback(): return message -class testHTTPServer_RequestHandler(BaseHTTPRequestHandler): +class HTTPRequestHandler(BaseHTTPRequestHandler): def do_GET(self): # Send response status code self.send_response(200) @@ -48,7 +48,8 @@ def do_GET(self): ps_core.de_init() CONFIG = ps_core.init(sys.argv[1]) - # Write content as utf-8 data + # Sent message back to client after replacing newlines with HTML line breaks + message = message.replace("\n", "
") self.wfile.write(message.encode("utf8")) return @@ -65,7 +66,7 @@ def run_server(): else: local_ip = socket.gethostbyname(socket.gethostname()) server_address = (local_ip, CONFIG["http_port"]) - httpd = HTTPServer(server_address, testHTTPServer_RequestHandler) + httpd = HTTPServer(server_address, HTTPRequestHandler) print("running server...") httpd.serve_forever() diff --git a/sync_ondemand.py b/sync_ondemand.py index 91b279d..ce1ced8 100644 --- a/sync_ondemand.py +++ b/sync_ondemand.py @@ -85,10 +85,10 @@ msg = MIMEText(body) msg["To"] = email_config["to"] - msg["From"] = email_config["from"] + msg["From"] = email_config["smtp"]["from"] msg["Subject"] = email_config["subject"] - with smtplib.SMTP(email_config["server"]) as smtp: + with smtplib.SMTP(email_config["smtp"]["server"]) as smtp: smtp.starttls() smtp.login( email_config["smtp"]["username"], email_config["smtp"]["password"]