DWStaging
 usp_DimInstitutionalRetentionCohortT2T_Select (Stored Procedure)
  Properties
Property Value
Name usp_DimInstitutionalRetentionCohortT2T_Select
Schema dbo
Is Encrypted False
Ansi Nulls Status True
Quoted Identifier Status True
Description
  Parameters
Name Data Type Direction Description
  Parent Dependencies (objects that usp_DimInstitutionalRetentionCohortT2T_Select depends on)
Name Type
Table
Table
Table
Table
Table
Table
Table
Table
  Child Dependencies (objects that depend on usp_DimInstitutionalRetentionCohortT2T_Select)
Name Type
TABLE
TABLE
TABLE
TABLE
TABLE
TABLE
TABLE
TABLE
  Extended Properties
Object Property Value
   Annotations
Object Property Value
  DDL
/****** Object: StoredProcedure [dbo].[usp_DimInstitutionalRetentionCohortT2T_Select] Script Date: 03/09/2017 16:47:10 ******/
SET ANSI_NULLS ON
SET QUOTED_IDENTIFIER ON
/*
Name:            usp_DimInstitutionalRetentionCohortT2T_Select
Title:            Primary Select for the Institutional Retention Cohort Dimension (Term To Term)
Date:            10/10/2013
System/Project:    Student Retention Dashboard
Description:    This procedure will combine the Student End of Term and Academic History information from DWStaging
to determine the Cohort Term for those students.
This is for the Term To Term cohorts only.
Revision History:
10/10/2013 Ian Peterson Created.
09/14/2015 Sophia Cowan - Changed LogTime to include 10th of second to retrieve the most current
- Added temp tables to only wok with Students that exist in EndOfTerm file
- Added a temp file to populate from Program Objective Log and reduce number of records
processed
- Remove MAX of Partition and replace with an OUTER APPLY statement
- Include Age Range and RowIsDuplicated and RowIsSelected columns
*/
CREATE PROC [dbo].[usp_DimInstitutionalRetentionCohortT2T_Select]
AS 
SET NOCOUNT ON
IF 2=3
    BEGIN
    SELECT
     CAST('aaa' AS varchar(30)) AS InstitutionalRetentionCohortAK
    ,CAST('aaa' AS varchar(9))  AS StudentId
    ,CAST(0 AS smallint)        AS CohortYear
    ,CAST('aaa' AS varchar(6))  AS CohortTerm
    ,CAST('aaa' AS varchar(30)) AS CohortTermTitle
    ,CAST('aaa' AS varchar(10)) AS FirstTerm_FT_PT
    ,CAST('aaa' AS varchar(15))    AS RetentionCohortTypeCode
    ,CAST('aaa' AS varchar(60))    AS RetentionCohortType
    ,CAST('aaa' AS varchar(5))  AS ProgramCode
    ,CAST('aaa' AS varchar(30)) AS Program
    ,CAST('aaa' AS varchar(3))  AS ProgramAdmitStatus
    ,CAST('aaa' AS varchar(3))  AS AwardTypeCode
    ,CAST('aaa' AS varchar(30)) AS AwardType
    ,CAST(0 as smallint)        AS AgeAtInstitutionalRetentionCohort
    ,CAST('aaa' AS varchar(10)) AS AgeRangeAtInstitutionalRetentionCohort
    ,CAST('a' AS CHAR(1)) AS RowIsDuplicate
    ,CAST('a' AS CHAR(1)) AS RowIsSelected
    END
/* Determine the number of hours required to be considered Full-Time and put into a local variable. */
DECLARE @FTHrs numeric
SET @FTHrs = (SELECT CAST(SUBSTRING(DESCRIPTION,1,4) AS NUMERIC) FROM UTL_CODE_TABLE
        WHERE TABLE_NAME = 'SITE-PARAM' 
            AND CODE = 'ENROLLMENT'
            AND [STATUS] = 'A')
IF @FTHrs IS NULL
BEGIN
    SET @FTHrs =         12/* Default to 12 hours if table does not exist. */
END
/* This table will contain all Terms and Start Dates for Terms existing in the ST-STDNT-ENDOFTERM table */
CREATE TABLE #Students
(
   StId VARCHAR(9) NOT NULL
)
INSERT INTO #Students
(
   StId
  )
  
SELECT 
  DISTINCT STDNT_ID AS StId
FROM ST_STDNT_ENDOFTERM_A StEndTerm
/* This table will contain all students and terms from the End Of Term table where the student took a credit class. */
CREATE TABLE #student_term_credit
    (
    [StudentId] VARCHAR(9)  NOT NULL
    ,[T2TCohortTerm] VARCHAR(6) NOT NULL
    )
INSERT INTO #student_term_credit
    (
     [StudentId]
    ,[T2TCohortTerm]
    )
    SELECT 
          EOT.STDNT_ID AS StudentId
          ,EOT.TRM_YR AS T2TCohortTerm
    FROM ST_STDNT_ENDOFTERM_A EOT
    /* Join on set of students that completed a local credit class in the term. */
    INNER JOIN (
            SELECT 
                AH1.STUDENT_ID 
                ,RTRIM(SUBSTRING(AH1.CLASS_KEY,12,6)) AS AH_TERM
            FROM ST_ACDMC_HIST_A AH1
            WHERE SUBSTRING(AH1.CLASS_KEY,1,1) = 'C'  /* Credit Class */
                AND AH1.SPCL_CRED_TY IS     NULL/* No test classes */
            GROUP BY AH1.STUDENT_ID, SUBSTRING(AH1.CLASS_KEY,12,6)
        ) AH
        ON (
            EOT.STDNT_ID = AH.STUDENT_ID
            AND EOT.TRM_YR = AH.AH_TERM
        )
    /* We are not interested in students who have a 'summer' cohort term. */
    WHERE
        SUBSTRING(EOT.TRM_YR,5,1) IN ('1','2')
/* This table will contain Program Objective data for Students on the End Of Term file. */
CREATE TABLE #PgmObjLog
(
     [StudentId] VARCHAR(9)  NOT NULL
    ,[PgmId] VARCHAR(5) NOT NULL
    ,[PgmEffTerm] VARCHAR(6) NOT NULL
    ,[AdmitStatus] VARCHAR(1) NOT NULL
    ,LogDateTime DATETIME NOT NULL
)
INSERT INTO #PgmObjLog
(
     [StudentId]
    ,[PgmId]
    ,[PgmEffTerm] 
    ,[AdmitStatus]
    ,LogDateTime
)
SELECT 
   STDNT_ID
  ,PGM_ID
  ,EFF_TERM
  ,ADMT_STAT
  ,CASE
     WHEN ISDATE(LOG_DATE) = 0 THEN '1900-01-01 00:00:00.000'
     WHEN LOG_TIME IS NULL THEN CONVERT(DATETIME, CONVERT(CHAR(8), LOG_DATE) + ' ' 
             + '00:00:00.000')
     ELSE CONVERT(DATETIME, CONVERT(CHAR(8), LOG_DATE) + ' ' 
             + STUFF(STUFF(STUFF(RIGHT('0000000' + cast(LOG_TIME as varchar(7)),7),3,0,':'),6,0,':'),9,0,'.'))
   END AS             LogDateTime               
FROM ST_STDNT_OBJ_AWD_LOG_A PgmObjLog
INNER JOIN #Students
ON
(
   #Students.StId = PgmObjLog.STDNT_ID
)
WHERE STDNT_ID IS NOT NULL 
            AND PGM_ID IS NOT NULL 
            AND EFF_TERM IS NOT NULL 
            AND PGM_STAT != 'IN'
            AND PgmObjLog.ADMT_STAT IS NOT NULL
            
   
/* This table will contain program objective log records prior to end of cohort term. */
CREATE TABLE #student_log_temp
    (
    [StudentId] VARCHAR(9)  NOT NULL
    ,[CohortProgram] VARCHAR(5) NOT NULL
    ,[CohortTerm] VARCHAR(6) NOT NULL
    ,[PgmEffTerm] VARCHAR(6)  NULL
    ,[MaxLogDateTime] DATETIME NULL
    ,[AdmitStatus] VARCHAR(1) NULL
    ,SessionEndDate DATETIME
    )
INSERT INTO #student_log_temp
    (
     [StudentId]
    ,[CohortProgram]
    ,[CohortTerm]
    ,[PgmEffTerm]
    ,[MaxLogDateTime]
    ,[AdmitStatus]
    ,SessionEndDate
    )
    /* Determine the students and admission status for all log records prior to end of cohort term */
    SELECT
        EndOfTerm.STDNT_ID AS StudentId
        ,EndOfTerm.PGM_ID AS CohortProgram
        ,EndOfTerm.TRM_YR AS CohortTerm
        ,MaxPgmObjLog.PgmEffTerm AS PgmEffTerm
        ,MaxPgmObjLog.MaxLogDateTime
        ,MaxPgmObjLog.AdmitStatus AS AdmitStatus
        ,Sess.SessionEndDate
    FROM ST_STDNT_ENDOFTERM_A EndOfTerm
    /* Inner Join on the End Of Term table so we only bring in students where the actual cohort term exists on that table */
    INNER JOIN #student_term_credit
        ON (
            EndOfTerm.STDNT_ID = #student_term_credit.StudentId
            AND EndOfTerm.TRM_YR = #student_term_credit.T2TCohortTerm
        )
    /* Retrieve the session end date for the cohort term */
    LEFT OUTER JOIN (
            SELECT 
               RTRIM(LTRIM(SUBSTRING(SESSION_KEY,1,6))) AS SessionTerm
              ,CAST(SESS_END_DT + ' ' + '23:59:59.000' AS DATETIME) AS SessionEndDate 
            FROM ST_SESSION_A
            WHERE SUBSTRING(SESSION_KEY,7,4) = '1 '  /* Session 1 = Main session */
        ) Sess
        ON (
            Sess.SessionTerm = EndOfTerm.TRM_YR
        )
        
   CROSS APPLY
   (
      SELECT TOP 1 
         StudentId
        ,PgmId
        ,PgmEffTerm
        ,LogDateTime AS MaxLogDateTime
        ,AdmitStatus
      FROM #PgmObjLog
      WHERE #PgmObjLog.StudentId = EndOfTerm.STDNT_ID
            AND #PgmObjLog.PgmId = EndOfTerm.PGM_ID 
             AND #PgmObjLog.PgmEffTerm <= EndOfTerm.TRM_YR
            AND #PgmObjLog.LogDateTime <= Sess.SessionEndDate
             
       GROUP BY StudentId, PgmId, PgmEffTerm, LogDateTime, AdmitStatus
       ORDER BY StudentId, PgmId, LogDateTime DESC, PgmEffTerm DESC, AdmitStatus
     ) AS MaxPgmObjLog
   
/* Now the MAIN Select statement. */
/* Get the students that have changed on the End Of Term table. */
SELECT
     CASE
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '1' THEN EndOfTerm.STDNT_ID + EndOfTerm.TRM_YR + ' ' + 'FallToSpring'
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '2' THEN EndOfTerm.STDNT_ID + EndOfTerm.TRM_YR + ' ' + 'SpringToFall'
        ELSE 'N/A'
        END AS InstitutionalRetentionCohortAK
    ,EndOfTerm.STDNT_ID AS StudentId
    ,LEFT(EndOfTerm.TRM_YR,4) AS CohortYear
    ,EndOfTerm.TRM_YR AS CohortTerm
    ,LTRIM(RTRIM(ISNULL(Term.TRM_TTL, 'N/A'))) AS CohortTermTitle
    ,CASE
        WHEN EndOfTerm.TRM_HRS_ATT >= @FTHrs THEN 'Full-time'
        ELSE 'Part-time'
        END AS FirstTerm_FT_PT
    ,CASE
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '1' THEN 'FallToSpring'
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '2' THEN 'SpringToFall'
        ELSE 'N/A'
        END AS RetentionCohortTypeCode
    ,CASE
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '1' THEN 'Fall To Spring Term Retention'
        WHEN SUBSTRING(EndOfTerm.TRM_YR,5,1) = '2' THEN 'Spring To Fall Term Retention'
        ELSE 'N/A'
        END AS RetentionCohortType
    ,LTRIM(RTRIM(EndOfTerm.PGM_ID)) AS ProgramCode
    ,CAST(CASE
            WHEN Program.PGM_SHRT_TTL IS NULL THEN 'N/A'
            WHEN SUBSTRING(Program.PGM_SHRT_TTL,1,30) <> '' THEN LTRIM(RTRIM(SUBSTRING(Program.PGM_SHRT_TTL,1,30)))
            ELSE LTRIM(RTRIM(SUBSTRING(Program.PGM_SHRT_TTL,31,30)))
        END
        AS varchar(30)) AS Program
    ,CAST(CASE
        WHEN PgmObjLog.AdmitStatus IS NULL THEN 'N/A'
        WHEN LTRIM(RTRIM(PgmObjLog.AdmitStatus)) = '' THEN 'N/A'
        WHEN PgmObjLog.AdmitStatus = 'Y' THEN 'Yes'
        ELSE 'No'
        END AS varchar(3)) AS ProgramAdmitStatus
    ,LTRIM(RTRIM(CAST(ISNULL(Program.AWD_TY, 'N/A') AS varchar(3)))) AS AwardTypeCode
    ,LTRIM(RTRIM(ISNULL(Award.DESCRIPTION, 'N/A'))) AS AwardType
    ,CAST(CASE 
        WHEN Stdnt.DOB IS NULL THEN 0 
        WHEN Sess.SESS_BEG_DT IS NULL THEN 0
        WHEN Stdnt.DOB > Sess.SESS_BEG_DT THEN 0
        -- When Age > 120, assume incorrect; set to 0.
        WHEN ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) > 120 THEN 0
        ELSE CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint )
        END AS smallint) AS AgeAtInstitutionalRetentionCohort
    ,CAST(CASE 
        WHEN Stdnt.DOB IS NULL THEN 'N/A' 
        WHEN Sess.SESS_BEG_DT IS NULL THEN 'N/A'
        WHEN Stdnt.DOB > Sess.SESS_BEG_DT THEN 'N/A'
        -- When Age > 120, assume incorrect; set to 0.
        WHEN ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) > 120 THEN 'N/A'
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 0
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 18 
            THEN '< 19'
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 18
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 21
            THEN '19 - 21'            
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 21
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 29
            THEN '22 - 29'    
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 29
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 39
            THEN '30 - 39'            
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 39
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 64
            THEN '39 - 64'                                            
        WHEN CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) > 65
          AND CAST(ROUND(DATEDIFF(day,CAST(Stdnt.DOB as date),CAST(Sess.SESS_BEG_DT AS date)) / 365.25,0,1) as smallint ) <= 120
            THEN 'Other'                        
        ELSE 'N/A'
        END AS VARCHAR(10)) AS     AgeRangeAtInstitutionalRetentionCohort
    ,CAST('N' AS CHAR(1)) AS RowIsDuplicate
    ,CAST('Y' AS CHAR(1)) AS             RowIsSelected
FROM ST_STDNT_ENDOFTERM_A EndOfTerm
/* Get Student Information */
LEFT OUTER JOIN ST_STDNT_A Stdnt
   ON (
       Stdnt.STUDENT_ID = EndOfTerm.STDNT_ID
      )
/* Inner Join on the End Of Term table so we only bring in students where the actual T2T cohort term exists on that table */
INNER JOIN #student_term_credit
    ON (
        EndOfTerm.STDNT_ID = #student_term_credit.StudentId
        AND EndOfTerm.TRM_YR = #student_term_credit.T2TCohortTerm
    )
/* Get Cohort Term Information */
LEFT OUTER JOIN (
        SELECT TRM_YR, TRM_TTL FROM ST_TERM_A
    ) Term
    ON (
        Term.TRM_YR = #student_term_credit.T2TCohortTerm
    )
/* Get Main Session Information (for term start date to calculate student age) */
LEFT OUTER JOIN ST_SESSION_A Sess
   ON (
        SUBSTRING(Sess.SESSION_KEY,1,6) = EndOfTerm.TRM_YR
            AND SUBSTRING(Sess.SESSION_KEY,7,4) = '1 '
      )
/* Join on the Programs-Demo record to get the award type of the Cohort Term program of study */
/* Gets the latest program-demo record to find award type and program description. */
CROSS APPLY (
    SELECT TOP 1
        PGM_CD, EFF_TRM_D, END_TRM, AWD_TY, PGM_SHRT_TTL FROM ST_PROGRAMS_A
    WHERE 
        PGM_CD IS NOT NULL AND EFF_TRM_D IS NOT NULL AND AWD_TY IS NOT NULL
            ANDST_PROGRAMS_A.PGM_CD = EndOfTerm.PGM_ID
    ORDER BY EFF_TRM_9S_COMP_D
    ) Program
/* Get Award Type code description */
LEFT OUTER JOIN (
        SELECT CODE, UTL_CODE_TABLE.DESCRIPTION FROM UTL_CODE_TABLE
        WHERE TABLE_NAME = 'AWARD-TYPE' AND UTL_CODE_TABLE.STATUS = 'A'
    ) Award
    ON (
        Award.CODE = Program.AWD_TY 
    )
/* Join on the latest Student Objective record (for the program and term) to get the admission status of the student */
LEFT OUTER JOIN #student_log_temp PgmObjLog
    ON (
        PgmObjLog.StudentId = EndOfTerm.STDNT_ID
        AND PgmObjLog.CohortProgram = EndOfTerm.PGM_ID
        AND PgmObjLog.CohortTerm = EndOfTerm.TRM_YR
    )
Powered by BI Documenter