DDL and Load Scripts

01 DDL (Creating and Permissioning Tables) Scripts

/*==============================================================*/
/* DBMS name:      Amazon Redshift Database                     */
/* Created on:     9/7/2023 12:14:46 PM                         */
/*==============================================================*/


drop table FACT_Person_Program_Observation_Quarter;

drop table FACT_Person_Program_Outcome;

drop table FACT_Person_Program_Participation;

drop table FACT_Person_UI_Wage;

drop table FACT_Person_Quarterly_Program_Enrollment;

drop table DIM_CIP;

drop table DIM_County;

drop table DIM_Intake_Characteristics;

drop table DIM_Person;

drop table DIM_Program;

drop table DIM_State;

drop table DIM_Year_Quarter;


/*==============================================================*/
/* Table: DIM_CIP                                               */
/*==============================================================*/
create table if not exists DIM_CIP (
   CIP_Key BIGINT not null,
   Classification_Code CHAR(7) not null,
   Classification_Name VARCHAR(300) not null,
   Category_Name VARCHAR(300) not null,
   Series_Name VARCHAR(300) not null,
   Series_Short_Name VARCHAR(300) not null,
   Major_Group_Code CHAR(2) not null,
   Major_Group_Name VARCHAR(300) not null,
   constraint DIM_CIP_PK_IDX primary key (CIP_Key),
    unique (Classification_Code)
);

/*==============================================================*/
/* Table: DIM_County                                            */
/*==============================================================*/
create table if not exists DIM_County (
   County_Key BIGINT not null,
   County_FIPS_Code CHAR(5) not null,
   County_Name VARCHAR(150) not null,
   Rural_Urban_Continuum VARCHAR(300) not null,
   Local_Workforce_Development_Area VARCHAR(30) not null,
   constraint DIM_COUNTY_PK_IDX primary key (County_Key),
    unique (County_FIPS_Code)
);

/*==============================================================*/
/* Table: DIM_Intake_Characteristics                            */
/*==============================================================*/
create table if not exists DIM_Intake_Characteristics (
   Intake_Characteristics_Key BIGINT not null,
   Highest_School_Grade_Completed_at_Program_Entry VARCHAR(2) not null,
   Highest_Education_Level_Completed_at_Program_Entry VARCHAR(100) not null,
   School_Status_at_Program_Entry VARCHAR(100) not null,
   Employment_Status_at_Program_Entry VARCHAR(100) not null,
   Long_Term_Unemployment_at_Program_Entry VARCHAR(3) not null,
   Exhausting_TANF_Within_2_Yrs_at_Program_Entry VARCHAR(3) not null,
   Foster_Care_Youth_Status_at_Program_Entry VARCHAR(3) not null,
   Homeless_or_Runaway_at_Program_Entry VARCHAR(3) not null,
   Ex_Offender_Status_at_Program_Entry VARCHAR(3) not null,
   Low_Income_Status_at_Program_Entry VARCHAR(3) not null,
   English_Language_Learner_at_Program_Entry VARCHAR(3) not null,
   Low_Levels_of_Literacy_at_Program_Entry VARCHAR(3) not null,
   Cultural_Barriers_at_Program_Entry VARCHAR(3) not null,
   Single_Parent_at_Program_Entry VARCHAR(3) not null,
   Displaced_Homemaker_at_Program_Entry VARCHAR(3) not null,
   constraint DIM_INTAKE_CHARACTERISTICS_PK_IDX primary key (Intake_Characteristics_Key)
);

/*==============================================================*/
/* Table: DIM_Person                                            */
/*==============================================================*/
create table if not exists DIM_Person (
   Person_Key BIGINT not null,
   Person_UID CHAR(64) not null,
   Date_of_Birth DATE not null,
   Gender VARCHAR(10) not null,
   Ethnicity_American_Indian_or_Alaska_Native VARCHAR(3) not null,
   Ethnicity_Asian VARCHAR(3) not null,
   Ethnicity_Black_or_African_American VARCHAR(3) not null,
   Ethnicity_Hispanic_or_Latino VARCHAR(3) not null,
   Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander VARCHAR(3) not null,
   Ethnicity_White VARCHAR(3) not null,
   Ethnicity_Other VARCHAR(3) not null,
   constraint DIM_PERSON_PK_IDX primary key (Person_Key),
    unique (Person_UID)
);

/*==============================================================*/
/* Table: DIM_Program                                           */
/*==============================================================*/
create table if not exists DIM_Program (
   Program_Key INTEGER not null,
   Program_Name VARCHAR(75) not null,
   constraint DIM_PROGRAM_PK_IDX primary key (Program_Key),
    unique (Program_Name)
);

/*==============================================================*/
/* Table: DIM_State                                             */
/*==============================================================*/
create table if not exists DIM_State (
   State_Key INTEGER not null,
   State_FIPS_Code CHAR(2) not null,
   State_Abbreviation CHAR(2) not null,
   State_Name VARCHAR(50) not null,
   constraint DIM_STATE_PK_IDX primary key (State_Key),
    unique (State_FIPS_Code),
    unique (State_Abbreviation)
);

/*==============================================================*/
/* Table: DIM_Year_Quarter                                      */
/*==============================================================*/
create table if not exists DIM_Year_Quarter (
   Year_Quarter_Key INTEGER not null,
   Calendar_Year CHAR(4) not null,
   Calendar_Quarter CHAR(1) not null,
   Quarter_Start_Date DATE not null,
   Quarter_End_Date DATE not null,
   constraint DIM_YEAR_QUARTER_PK_IDX primary key (Year_Quarter_Key),
    unique (Calendar_Year, Calendar_Quarter)
);

/*==============================================================*/
/* Table: FACT_Person_Program_Observation_Quarter               */
/*==============================================================*/
create table if not exists FACT_Person_Program_Observation_Quarter (
   Person_Program_Observation_Quarter_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Program_Key INTEGER not null,
   Observation_Year_Quarter_Key INTEGER not null,
   County_of_Residence_Key BIGINT not null,
   State_of_Residence_Key INTEGER not null,
   CIP_Classification_Key BIGINT not null,
   Enrolled_Entire_Quarter VARCHAR(3) not null,
   Enrolled_First_Month_of_Quarter VARCHAR(3) not null,
   Enrolled_Second_Month_of_Quarter VARCHAR(3) not null,
   Enrolled_Third_Month_of_Quarter VARCHAR(3) not null,
   Gross_Monthly_Income DECIMAL(14,2),
   Net_Monthly_Income DECIMAL(14,2),
   Date_of_Most_Recent_Career_Service DATE,
   Received_Training VARCHAR(3) not null,
   Eligible_Training_Provider_Name VARCHAR(75) not null,
   Eligible_Training_Provider_Program_of_Study VARCHAR(100) not null,
   Date_Entered_Training_1 DATE,
   Type_of_Training_Service_1 VARCHAR(100) not null,
   Date_Entered_Training_2 DATE,
   Type_of_Training_Service_2 VARCHAR(100) not null,
   Date_Entered_Training_3 DATE,
   Type_of_Training_Service_3 VARCHAR(100) not null,
   Participated_in_Postsecondary_Education_During_Program_Participation VARCHAR(3) not null,
   Received_Training_from_Private_Section_Operated_Program VARCHAR(3) not null,
   Enrolled_in_Secondary_Education_Program VARCHAR(3) not null,
   Date_Enrolled_in_Post_Exit_Education_or_Training_Program DATE,
   Youth_2nd_Quarter_Placement VARCHAR(50),
   Youth_4th_Quarter_Placement VARCHAR(50),
   Other_Reason_for_Exit VARCHAR(50) not null,
   Migrant_and_Seasonal_Farmworker_Status VARCHAR(50) not null,
   Individual_with_a_Disability VARCHAR(3) not null,
   Zip_Code_of_Residence CHAR(5) not null,
   Higher_Education_Student_Level VARCHAR(100) not null,
   Higher_Education_Enrollment_Status VARCHAR(100) not null,
   Higher_Education_Tuition_Status VARCHAR(100) not null,
   constraint FACT_PERSON_PROGRAM_OBSERVATION_QUARTER_PK_IDX primary key (Person_Program_Observation_Quarter_ID),
    unique (Person_Key, Program_Key, Observation_Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_PERSON foreign key (Person_Key) 
      references DIM_Person (Person_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_PROGRAM foreign key (Program_Key) 
      references DIM_Program (Program_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_YEAR_QUARTER foreign key (Observation_Year_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_COUNTY foreign key (County_of_Residence_Key) 
      references DIM_County (County_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_STATE foreign key (State_of_Residence_Key) 
      references DIM_State (State_Key),
   constraint FK_FACT_PERSON_PROGRAM_OBSERVATION_QUARTER__DIM_CIP foreign key (CIP_Classification_Key) 
      references DIM_CIP (CIP_Key)
);

/*==============================================================*/
/* Table: FACT_Person_Program_Outcome                           */
/*==============================================================*/
create table if not exists FACT_Person_Program_Outcome (
   Person_Program_Outcomes_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Program_Key INTEGER not null,
   Exit_Year_Quarter_Key INTEGER not null,
   Employed_in_1st_Quarter_After_Exit_Quarter VARCHAR(30) not null,
   Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter VARCHAR(50) not null,
   Earnings_1st_Quarter_After_Exit_Quarter DECIMAL(9,2),
   Employed_in_2nd_Quarter_After_Exit_Quarter VARCHAR(30) not null,
   Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter VARCHAR(50) not null,
   Earnings_2nd_Quarter_After_Exit_Quarter DECIMAL(9,2),
   Employed_in_3rd_Quarter_After_Exit_Quarter VARCHAR(30) not null,
   Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter VARCHAR(50) not null,
   Earnings_3rd_Quarter_After_Exit_Quarter DECIMAL(9,2),
   Employed_in_4th_Quarter_After_Exit_Quarter VARCHAR(30) not null,
   Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter VARCHAR(50) not null,
   Earnings_4th_Quarter_After_Exit_Quarter DECIMAL(9,2),
   Employment_Related_to_Training VARCHAR(3),
   Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter VARCHAR(3) not null,
   Type_of_Recognized_Credential_1 VARCHAR(100) not null,
   Type_of_Recognized_Credential_2 VARCHAR(100) not null,
   Type_of_Recognized_Credential_3 VARCHAR(100) not null,
   Date_Attained_Recognized_Credential_1 DATE,
   Date_Attained_Recognized_Credential_2 DATE,
   Date_Attained_Recognized_Credential_3 DATE,
   Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level DATE,
   Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript DATE,
   Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript DATE,
   Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone DATE,
   Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression DATE,
   Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment DATE,
   Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment DATE,
   Date_Attained_Graduate_or_Post_Graduate_Degree DATE,
   constraint FACT_PERSON_PROGRAM_OUTCOME_PK_IDX primary key (Person_Program_Outcomes_ID),
    unique (Person_Key, Program_Key, Exit_Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_OUTCOME__DIM_PERSON foreign key (Person_Key) 
      references DIM_Person (Person_Key),
   constraint FK_FACT_PERSON_PROGRAM_OUTCOME__DIM_PROGRAM foreign key (Program_Key) 
      references DIM_Program (Program_Key),
   constraint FK_FACT_PERSON_PROGRAM_OUTCOME__DIM_YEAR_QUARTER foreign key (Exit_Year_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key)
);

/*==============================================================*/
/* Table: FACT_Person_Program_Participation                     */
/*==============================================================*/
create table if not exists FACT_Person_Program_Participation (
   Person_Program_Participation_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Intake_Characteristics_Key BIGINT not null,
   Program_Key INTEGER not null,
   Entry_Year_Quarter_Key INTEGER not null,
   Exit_Year_Quarter_Key INTEGER not null,
   County_of_Residence_Key BIGINT not null,
   State_of_Residence_Key INTEGER not null,
   CIP_Classification_Key BIGINT not null,
   Gross_Monthly_Income DECIMAL(14,2),
   Net_Monthly_Income DECIMAL(14,2),
   Date_of_Most_Recent_Career_Service DATE,
   Received_Training VARCHAR(3) not null,
   Eligible_Training_Provider_Name VARCHAR(75) not null,
   Eligible_Training_Provider_Program_of_Study VARCHAR(100) not null,
   Date_Entered_Training_1 DATE,
   Type_of_Training_Service_1 VARCHAR(100) not null,
   Date_Entered_Training_2 DATE,
   Type_of_Training_Service_2 VARCHAR(100) not null,
   Date_Entered_Training_3 DATE,
   Type_of_Training_Service_3 VARCHAR(100) not null,
   Participated_in_Postsecondary_Education_During_Program_Participation VARCHAR(3) not null,
   Received_Training_from_Private_Section_Operated_Program VARCHAR(3) not null,
   Enrolled_in_Secondary_Education_Program VARCHAR(3) not null,
   Date_Enrolled_in_Post_Exit_Education_or_Training_Program DATE,
   Youth_2nd_Quarter_Placement VARCHAR(50),
   Youth_4th_Quarter_Placement VARCHAR(50),
   Incarcerated_at_Program_Entry VARCHAR(3) not null,
   Date_Released_from_Incarceration DATE,
   Other_Reason_for_Exit VARCHAR(50) not null,
   Migrant_and_Seasonal_Farmworker_Status VARCHAR(50) not null,
   Individual_with_a_Disability VARCHAR(3) not null,
   Zip_Code_of_Residence CHAR(5) not null,
   Higher_Education_Student_Level VARCHAR(100) not null,
   Higher_Education_Enrollment_Status VARCHAR(100) not null,
   Higher_Education_Tuition_Status VARCHAR(100) not null,
   constraint FACT_PERSON_PROGRAM_PARTICIPATION_PK_IDX primary key (Person_Program_Participation_ID),
    unique (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_PROGRAM foreign key (Program_Key) 
      references DIM_Program (Program_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_YEAR_QUARTER__ENTRY_YEAR foreign key (Entry_Year_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_PERSON foreign key (Person_Key) 
      references DIM_Person (Person_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_YEAR_QUARTER__EXIT_YEAR foreign key (Exit_Year_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_INTAKE_CHARACTERISTICS foreign key (Intake_Characteristics_Key) 
      references DIM_Intake_Characteristics (Intake_Characteristics_Key),
   constraint FK_FACT_PERSON_PROGRAM_PARTICIPATION__DIM_COUNTY foreign key (County_of_Residence_Key) 
      references DIM_County (County_Key),
   constraint FK_FACT_PERSON_PROGRAM__FACT_PERSON_PROGRAM_PARTICIPATION__DIM_CIP_DIM_CIP foreign key (CIP_Classification_Key) 
      references DIM_CIP (CIP_Key),
   constraint FK_FACT_PERSON_PROGRAM__FACT_PERSON_PROGRAM_PARTICIPATION__DIM_STATE_DIM_STATE foreign key (State_of_Residence_Key) 
      references DIM_State (State_Key)
);

/*==============================================================*/
/* Table: FACT_Person_UI_Wage                                   */
/*==============================================================*/
create table if not exists FACT_Person_UI_Wage (
   Person_UI_Wage_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Year_Quarter_Key INTEGER not null,
   UI_Quarterly_Wages DECIMAL(10,0) not null,
   constraint FACT_PERSON_UI_WAGE_PK_IDX primary key (Person_UI_Wage_ID),
    unique (Person_Key, Year_Quarter_Key),
   constraint FK_FACT_PERSON_UI_WAGE__DIM_PERSON foreign key (Person_Key) 
      references DIM_Person (Person_Key),
   constraint FK_FACT_PERSON_UI_WAGE__DIM_YEAR_QUARTER foreign key (Year_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key)
);

/*==============================================================*/
/* Table: FACT_Person_Quarterly_Program_Enrollment              */
/*==============================================================*/
create table if not exists FACT_Person_Quarterly_Program_Enrollment (
   Person_Quarterly_Program_Enrollment_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Program_Key INTEGER not null,
   Enrollment_Quarter_Key INTEGER not null,
   Enrolled_Entire_Quarter VARCHAR(3) not null,
   Enrolled_First_Month_of_Quarter VARCHAR(3) not null,
   Enrolled_Second_Month_of_Quarter VARCHAR(3) not null,
   Enrolled_Third_Month_of_Quarter VARCHAR(3) not null,
   constraint PK_FACT_Person_Quarterly_Program_Enrollment primary key (Person_Quarterly_Program_Enrollment_ID),
    unique (Person_Key, Program_Key, Enrollment_Quarter_Key),
   constraint FK_FACT_PERSON_QUARTERLY_PROGRAM_ENROLLMENT_DIM_PROGRAM foreign key (Program_Key) 
      references DIM_Program (Program_Key),
   constraint FK_FACT_PERSON_QUARTERLY_PROGRAM_ENROLLMENT_DIM_YEAR_QUARTER foreign key (Enrollment_Quarter_Key) 
      references DIM_Year_Quarter (Year_Quarter_Key),
   constraint FK_FACT_PERSON_QUARTERLY_PROGRAM_ENROLLMENT_DIM_PERSON foreign key (Person_Key) 
      references DIM_Person (Person_Key)
);

GRANT SELECT ON TABLE DIM_Person TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE DIM_Person TO group db_t00113_rw;

GRANT SELECT ON TABLE DIM_Program TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE DIM_Program TO group db_t00113_rw;

GRANT SELECT ON TABLE DIM_Intake_Characteristics TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE DIM_Intake_Characteristics TO group db_t00113_rw;

GRANT SELECT ON TABLE DIM_Year_Quarter TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE DIM_Year_Quarter TO group db_t00113_rw;

GRANT SELECT ON TABLE DIM_County TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE DIM_County TO group db_t00113_rw;

GRANT SELECT ON TABLE FACT_Person_Program_Observation_Quarter TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE FACT_Person_Program_Observation_Quarter TO group db_t00113_rw;

GRANT SELECT ON TABLE FACT_Person_Program_Outcome TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE FACT_Person_Program_Outcome TO group db_t00113_rw;

GRANT SELECT ON TABLE FACT_Person_Program_Participation TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE FACT_Person_Program_Participation TO group db_t00113_rw;

GRANT SELECT ON TABLE FACT_Person_UI_Wage TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE FACT_Person_UI_Wage TO group db_t00113_rw;

GRANT SELECT ON TABLE FACT_Person_Quarterly_Program_Enrollment TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, INSERT ON TABLE FACT_Person_Quarterly_Program_Enrollment TO group db_t00113_rw;

02 Load Scripts

FACT Person Outcome Tables

JOINT PIRL

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Adult Education (JOINT)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.jointpirl_raw_data) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (Joint PIRL)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Adult Education (JOINT)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.jointpirl_raw_data
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND ssn_valid_format = 1
    AND adult_education_wioa = 1
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Adult Education

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Adult Education (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Adult Education)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Adult Education (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.adult_education_wioa = 1
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Adult

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Adult (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Adult)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Adult (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.adult_wioa IN (1, 2, 3)
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Dislocated Worker

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Dislocated Worker (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Dislocated Worker)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Dislocated Worker (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.dislocated_worker_wioa IN (1, 2, 3)
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Job Corps

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Job Corps (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Job Corps)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Job Corps (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.job_corps_wioa = 1
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Vocational Rehab

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Vocational Rehabilitation (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Vocational Rehab)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Vocational Rehabilitation (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.vocational_rehabilitation_wioa IN (1, 2, 3)
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Wagner Peyser

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Wagner-Peyser Employment Service (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Wagner Peyser)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Wagner-Peyser Employment Service (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.wagner_peyser_employment_service_wioa = 1
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Youth Builder

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "YouthBuild (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Youth Build)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('YouthBuild (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.youthbuild_wioa IS NOT NULL
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

Youth

/*
  This script will load the the FACT_Person_Program_Outcome table with data for the "Youth (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Outcome (PIRL - Youth)
INSERT INTO FACT_Person_Program_Outcome (Person_Key, Program_Key, Exit_Year_Quarter_Key, Employed_in_1st_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
                                         Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
                                         Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
                                         Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
                                         Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
                                         Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
                                         Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
                                         Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
                                         Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
                                         Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
                                         Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
                                         Date_Attained_Graduate_or_Post_Graduate_Degree)
WITH ctePirl (social_security_number, program_name, exit_date, Employed_in_1st_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
              Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
              Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
              Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
              Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
              Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
              Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
              Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
              Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
              Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
              Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
              Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
              Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
              Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
              Date_Attained_Graduate_or_Post_Graduate_Degree)
AS
(
    SELECT  social_security_number,
            CAST('Youth (WIOA)' AS VARCHAR(75)) AS program_name,
            date_of_program_exit_wioa,
            CASE
                WHEN employed_in_1st_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_1st_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_1st_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_2nd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_2nd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_2nd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_3rd_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_3rd_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_3rd_quarter_after_exit_quarter_wioa, 0),
            CASE
                WHEN employed_in_4th_quarter_after_exit_quarter_wioa IN (1, 2, 3) THEN 'Yes'
                ELSE 'No'
            END,
            CASE type_of_employment_match_4th_quarter_after_exit_quarter_wioa
                WHEN 1 THEN 'UI Wage Data'
                WHEN 2 THEN 'Federal Employment Records (OPM, USPS)'
                WHEN 3 THEN 'Military Employment Records (DOD)'
                WHEN 4 THEN 'Non UI verification'
                WHEN 5 THEN 'Information not yet available'
                WHEN 0 THEN 'Not employed'
                ELSE ''
            END,
            COALESCE(earnings_4th_quarter_after_exit_quarter_wioa, 0),
            CASE employment_related_to_training_2nd_quarter_after_exit_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE retention_with_the_same_employer_in_the_2nd_quarter_and_the_4th_quarter_wioa
                WHEN 1 THEN 'Yes'
                WHEN 0 THEN 'No'
                ELSE ''
            END,
            CASE type_of_recognized_credential_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_2_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            CASE type_of_recognized_credential_3_wioa
                WHEN 1 THEN 'Secondary School Diploma/or equivalency'
                WHEN 2 THEN 'AA or AS Diploma/Degree'
                WHEN 3 THEN 'BA or BS Diploma/Degree'
                WHEN 4 THEN 'Occupational Licensure'
                WHEN 5 THEN 'Occupational Certificate'
                WHEN 6 THEN 'Occupational Certification'
                WHEN 7 THEN 'Other Recognized Diploma, Degree, or Certificate'
                WHEN 0 THEN 'No recognized credential'
                ELSE ''
            END,
            COALESCE(date_attained_recognized_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_2_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_recognized_credential_3_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_educational_functioning_level_efl_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_postsecondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_secondary_transcript_report_card_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_training_milestone_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_of_most_recent_measurable_skill_gains_skills_progression_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            COALESCE(date_completed_during_program_participation_an_education_or_training_program_leading_to_a_recognized_credential_or_employment, CAST('9999-01-01' AS DATE)),
            COALESCE(date_attained_graduate_post_graduate_degree_wioa, CAST('9999-01-01' AS DATE))
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_exit_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youth_wioa IN (1, 2, 3)
),
cteFactData
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            pirl.Employed_in_1st_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter,
            pirl.Earnings_1st_Quarter_After_Exit_Quarter,
            pirl.Employed_in_2nd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
            pirl.Earnings_2nd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_3rd_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter,
            pirl.Earnings_3rd_Quarter_After_Exit_Quarter,
            pirl.Employed_in_4th_Quarter_After_Exit_Quarter,
            pirl.Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
            pirl.Earnings_4th_Quarter_After_Exit_Quarter,
            pirl.Employment_Related_to_Training,
            pirl.Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter,
            pirl.Type_of_Recognized_Credential_1,
            pirl.Type_of_Recognized_Credential_2,
            pirl.Type_of_Recognized_Credential_3,
            pirl.Date_Attained_Recognized_Credential_1,
            pirl.Date_Attained_Recognized_Credential_2,
            pirl.Date_Attained_Recognized_Credential_3,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
            pirl.Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
            pirl.Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
            pirl.Date_Attained_Graduate_or_Post_Graduate_Degree
    FROM ctePirl pirl
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        Employed_in_1st_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_1st_Quarter_After_Exit_Quarter, Earnings_1st_Quarter_After_Exit_Quarter,
        Employed_in_2nd_Quarter_After_Exit_Quarter, Type_of_Employment_Match_2nd_Quarter_After_Exit_Quarter,
        Earnings_2nd_Quarter_After_Exit_Quarter, Employed_in_3rd_Quarter_After_Exit_Quarter,
        Type_of_Employment_Match_3rd_Quarter_After_Exit_Quarter, Earnings_3rd_Quarter_After_Exit_Quarter,
        Employed_in_4th_Quarter_After_Exit_Quarter, Type_of_Employment_Match_4th_Quarter_After_Exit_Quarter,
        Earnings_4th_Quarter_After_Exit_Quarter, Employment_Related_to_Training,
        Retention_with_Same_Employer_2nd_Quarter_and_4th_Quarter, Type_of_Recognized_Credential_1,
        Type_of_Recognized_Credential_2, Type_of_Recognized_Credential_3, Date_Attained_Recognized_Credential_1,
        Date_Attained_Recognized_Credential_2, Date_Attained_Recognized_Credential_3,
        Date_of_Most_Recent_Measurable_Skill_Gain_Educational_Functional_Level,
        Date_of_Most_Recent_Measurable_Skill_Gain_Postsecondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Secondary_Transcript,
        Date_of_Most_Recent_Measurable_Skill_Gain_Training_Milestone,
        Date_of_Most_Recent_Measurable_Skill_Gain_Skills_Progression,
        Date_Enrolled_in_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Completed_an_Education_or_Training_Program_Leading_to_Credential_or_Employment,
        Date_Attained_Graduate_or_Post_Graduate_Degree
FROM cteFactData;

FACT Person Program Observation Quarter Tables

Higher Education

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Higher Education" program.
    Step 1
        Try to remove duplicated higher education records by grouping on ssn, entry quarter, and exit quarter and selecting
            the minium academic_year and miniumum term for each grouping.
        The entry and exit quarters are calculated using academic_year and term.  Academic_year has to be adjusted to calendar year. 
    Step 2
        Collect data for each record found in step 1.
        The results are returned in the cteHigherEducation CTE.
    Step 3
        Lookup the dimension keys for each cteHigherEducation record.
        The results are returned in the cteFactData CTE.
    Step 4
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (Higher Education)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH cteDeDuplicate (social_security_number, Observation_Year_Quarter_Key, academic_year, academic_term, qtr_first_month, qtr_second_month, qtr_third_month)
AS
(
    SELECT  se.ssn_id AS social_security_number,
            obs_qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            MIN(se.academic_year),
            MIN(se.term) AS academic_term,
            MAX(CASE WHEN se.term IN ('3', '7') THEN 'No' ELSE 'Yes' END) AS first_month_qtr,
            CAST('Yes' AS CHAR(3)) AS second_month_qtr,
            MAX(CASE WHEN se.term IN ('0', '4') THEN 'No' ELSE 'Yes' END) AS third_month_qtr
    FROM ds_ar_dhe.student_enrollment_table se
    INNER JOIN DIM_Year_Quarter obs_qtr
        ON obs_qtr.calendar_year = CASE WHEN se.term IN ('1', '5') THEN CAST(CAST(se.academic_year AS INT) - 1 AS CHAR(4)) ELSE se.academic_year END
        AND obs_qtr.calendar_quarter = CASE WHEN se.term IN ('0', '4') THEN '3' WHEN se.term IN ('1', '5') THEN '4' WHEN se.term IN ('2', '6') THEN '1' WHEN se.term IN ('3', '7') THEN '2' END
    WHERE se.academic_year >= '2011'
    AND se.ssn_valid_format = 'Y'
    AND se.term IN ('0', '1', '2', '3', '4', '5', '6', '7')
    GROUP BY se.ssn_id, obs_qtr.Year_Quarter_Key
),
cteHigherEducation (social_security_number, program_name, Observation_Year_Quarter_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                    Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, County_FIPS_Code, state_abbreviation, cip_code, cip_detail,
                    Participated_in_Postsecondary_Education_During_Program_Participation, Enrolled_in_Secondary_Education_Program,
                    Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  cteDeDuplicate.social_security_number,
            CAST('Higher Education' AS VARCHAR(75)) AS program_name,
            cteDeDuplicate.Observation_Year_Quarter_Key,
            CASE
                WHEN cteDeDuplicate.qtr_first_month = 'Yes' AND cteDeDuplicate.qtr_second_month = 'Yes' AND cteDeDuplicate.qtr_third_month = 'Yes' THEN 'Yes'
                ELSE 'No'
            END AS Enrolled_Entire_Quarter,
            cteDeDuplicate.qtr_first_month AS Enrolled_First_Month_of_Quarter,
            cteDeDuplicate.qtr_second_month AS Enrolled_Second_Month_of_Quarter,
            cteDeDuplicate.qtr_third_month AS Enrolled_Third_Month_of_Quarter,
            COALESCE(se.geo_county, '') AS County_FIPS_Code,
            COALESCE(se.geo_state, '') AS state_abbreviation,
            COALESCE(dfy.cip_code, '') AS cip_code,
            COALESCE(dfy.cip_detail, '') AS cip_detail,
            CAST('Yes' AS CHAR(3)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('Yes' AS CHAR(3)) AS Enrolled_in_Secondary_Education_Program,
            COALESCE(rsl.descr, '') AS Higher_Education_Student_Level,
            COALESCE(res.descr, '') AS Higher_Education_Enrollment_Status,
            COALESCE(rts.descr, '') AS Higher_Education_Tuition_Status
    FROM ds_ar_dhe.student_enrollment_table se
    INNER JOIN cteDeDuplicate
        ON se.ssn_id = cteDeDuplicate.social_security_number
        AND se.academic_year = cteDeDuplicate.academic_year
        and se.term = cteDeDuplicate.academic_term
    LEFT JOIN ds_ar_dhe.degree_fice_year_Table dfy
        ON se.fice_code = dfy.fice_code
        AND se.academic_year = dfy.academic_year
        AND se.major_1 = dfy.degree_code
    LEFT JOIN ds_ar_dhe.refenrollstatus res
        ON se.enroll_status = res.enrollstatusid
    LEFT JOIN ds_ar_dhe.refstudentlevel rsl
        ON se.student_level = rsl.countryid     -- note: The name of the PK for this table is probably a typo (i.e. incorrect)
    LEFT JOIN ds_ar_dhe.reftuitionstatus rts
        ON se.tuition_status = rts.tuitionstatusid
    WHERE se.academic_year >= '2011'
    AND se.ssn_valid_format = 'Y'
),
cteFactData (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
             Participated_in_Postsecondary_Education_During_Program_Participation,  Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement,
             Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
 AS
 (
     SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = he.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = he.program_name
            ) AS Program_Key,
            --Observation Year Quarter Surrogate Key
            he.Observation_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = he.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = he.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = CONCAT(he.cip_code, CONCAT(CAST('.' AS CHAR(1)), he.cip_detail))
            ) AS CIP_Classification_Key,
            --Measures
            he.Enrolled_Entire_Quarter,
            he.Enrolled_First_Month_of_Quarter,
            he.Enrolled_Second_Month_of_Quarter,
            he.Enrolled_Third_Month_of_Quarter,
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            he.Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            he.Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            he.Higher_Education_Student_Level,
            he.Higher_Education_Enrollment_Status,
            he.Higher_Education_Tuition_Status
    FROM cteHigherEducation he
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Observation_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status, 
        Higher_Education_Tuition_Status
FROM cteFactData;

Joint PIRL

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Adult Education (JOINT)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.jointpirl_raw_data) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (Joint PIRL)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
              Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult Education (JOINT)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa AS entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CAST('9999-01-01' AS DATE),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CAST('9999-01-01' AS DATE),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END
    FROM ds_ar_dws.jointpirl_raw_data
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND ssn_valid_format = 1
    AND adult_education_wioa = 1
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date between entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,  -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,     -- source data does not contain gross monthly income
            0 AS Net_Monthly_Income,       -- source data does not contain net monthly income
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            CAST('' AS VARCHAR(5)) AS Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            pirl.entry_date,
            pirl.exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,            
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Adult Education

/*
  This script will load thefffflsfll FACT_Person_Program_Observation_Quarter table with data for the "Adult Education (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - adult education)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult Education (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.adult_education_wioa = 1
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Adult

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Adult (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - adult)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.adult_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Dislocated Worker

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Dislocated Worker (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - dislocated worker)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Dislocated Worker (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.dislocated_worker_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

Pirl - Job Corps

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Job Corps (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - job corps)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Job Corps (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.job_corps_wioa = 1
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Vocational Rehab

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Vocational Rehabilitation (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - vocational rehab)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Vocational Rehabilitation (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.vocational_rehabilitation_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Wagner Peyser

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Wagner-Peyser Employment Service (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - wagner peyser)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Wagner-Peyser Employment Service (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.wagner_peyser_employment_service_wioa = 1
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Youth Build

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "YouthBuild (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - youth build)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('YouthBuild (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND pirl.youthbuild_wioa IS NOT NULL
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

PIRL - Youth

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Youth (WIOA)" program.
    Step 1
        The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
        Any reference values or boolean values are converted to text strings.
    Step 2
        The ctePirl data is then process in the cteFactData CTE which looks up the dimension keys.
    Step 3
        The cteFactData data is duplicated for each quarter in the range of entry_quarter and exit_quarter and returned in cteResults.
    Step 4
        The cteResults is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (PIRL - youth)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Youth (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, GETDATE()) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship'
                WHEN '10' THEN 'Youth Occupational Skills Training'
                WHEN '11' THEN 'Other Non-Occupational-Skills Training'
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training'
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youth_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement,  Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status,
             entry_date, exit_date)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status,
            entry_date,
            exit_date
    FROM ctePirl pirl
),
cteResults (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
            Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
            Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation, 
            Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
            Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  COALESCE(Person_Key, 0),
            COALESCE(Program_Key, 0),
            qtr.Year_Quarter_Key AS Observation_Year_Quarter_Key,
            COALESCE(County_of_Residence_Key, 0),
            COALESCE(State_of_Residence_Key, 0),
            COALESCE(CIP_Classification_Key, 0),
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (1, 4, 7, 10) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (1, 4, 7, 10) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_First_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (2, 5, 8, 11) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (2, 5, 8, 11) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteFactData.Entry_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.entry_date) NOT IN (3, 6, 9, 12) THEN 'No'
                WHEN qtr.Year_Quarter_Key = cteFactData.Exit_Year_Quarter_Key AND DATEPART(MONTH, cteFactData.exit_date) NOT IN (3, 6, 9, 12) THEN 'No'
                ELSE 'Yes'
            END AS Enrolled_Third_Month_of_Quarter,
            Gross_Monthly_Income,
            Net_Monthly_Income,
            Date_of_Most_Recent_Career_Service,
            Received_Training,
            Eligible_Training_Provider_Name,
            Eligible_Training_Provider_Program_of_Study,
            Date_Entered_Training_1,
            Type_of_Training_Service_1,
            Date_Entered_Training_2,
            Type_of_Training_Service_2,
            Date_Entered_Training_3,
            Type_of_Training_Service_3,
            Participated_in_Postsecondary_Education_During_Program_Participation,
            Received_Training_from_Private_Section_Operated_Program,
            Enrolled_in_Secondary_Education_Program,
            Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            Youth_2nd_Quarter_Placement,
            Youth_4th_Quarter_Placement,
            Other_Reason_for_Exit,
            Migrant_and_Seasonal_Farmworker_Status,
            Individual_with_a_Disability,
            Zip_Code_of_Residence,
            Higher_Education_Student_Level,
            Higher_Education_Enrollment_Status,
            Higher_Education_Tuition_Status
    FROM cteFactData
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteFactData.Entry_Year_Quarter_Key AND cteFactData.Exit_Year_Quarter_Key
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        Observation_Year_Quarter_Key,
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        CASE
            WHEN Enrolled_First_Month_of_Quarter = 'Yes' AND Enrolled_Second_Month_of_Quarter = 'Yes' AND Enrolled_Third_Month_of_Quarter = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteResults;

SNAP

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Supplemental Nutrition Assistance Program (SNAP)" program.
    Step 1
        Find unique eligible cases and associate each unique case with a entry quarter and an exit quarter.
        The cert_start_date is used to determine the entry quarter and the cert_end_date is used to determine the exit quarter.
        The results are returned in the cteSNAPEligibleCase common table expression (CTE).
    Step 2
        Sum gross_monthly_income and net_monthly_income grouping on case, ssn, start quarter and exit quarter.
        The results are returned in the cteSNAPIncome CTE.
    Step 3
        Collect data for each case found in step 1 and supplement that data with the aggregated income values from step 2.
        The results are returned in the cteSNAP CTE.
    Step 4
        Lookup the dimension keys for eacn cteSNap record.
        The results are returned in the cteFactData CTE.
    Step 5
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (SNAP)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH cteSNAPEligibleCase (case_unit_id, year_qtr_key, start_file_date, end_file_date)
AS
(
    SELECT  snap_case.case_unit_id,
            obs_qtr.Year_Quarter_Key AS year_qtr_key,
            MIN(file_month) AS start_file_date,
            MAX(file_month) AS end_file_date
    FROM ds_ar_dhs.snap_case
    INNER JOIN DIM_Year_Quarter obs_qtr
        ON snap_case.file_month BETWEEN obs_qtr.Quarter_Start_Date AND obs_qtr.Quarter_End_Date
    WHERE DATEPART(YEAR, snap_case.file_month) >= 2010
    AND snap_case.snap_eligibility = 1
    AND snap_case.file_month BETWEEN snap_case.cert_start_date AND snap_case.cert_end_date
    GROUP BY snap_case.case_unit_id, obs_qtr.Year_Quarter_Key
),
cteSNAPIncome (case_unit_id, social_security_number, year_qtr_key, qtr_first_month, qtr_second_month,
               qtr_third_month, gross_monthly_income, net_monthly_income, file_month)
AS
(
    SELECT  sec.case_unit_id,
            si.SSN AS social_security_number,
            sec.year_qtr_key,
            MAX(CASE WHEN DATEPART(MONTH, si.file_month) IN (1, 4, 7, 10) THEN 'Yes' ELSE 'No' END) AS qtr_first_month,
            MAX(CASE WHEN DATEPART(MONTH, si.file_month) IN (2, 5, 8, 11) THEN 'Yes' ELSE 'No' END) AS qtr_second_month,
            MAX(CASE WHEN DATEPART(MONTH, si.file_month) IN (3, 6, 9, 12) THEN 'Yes' ELSE 'No' END) AS qtr_third_month,
            SUM(CASE WHEN si.gross_income_mo_indicator = 1 THEN si.gross_income_mo ELSE 0 END) AS gross_monthly_income,
            SUM(CASE WHEN si.net_income_mo_indicator = 1 THEN si.net_income_mo ELSE 0 END) AS net_monthly_income,
            MIN(si.file_month)
    FROM cteSNAPEligibleCase sec
    INNER JOIN ds_ar_dhs.snap_individual si
        ON sec.case_unit_id = si.case_unit_id
        AND si.file_month BETWEEN sec.start_file_date AND sec.end_file_date
    WHERE si.valid_ssn_format = 1
    AND si.ssn NOT IN (SELECT DISTINCT ssn FROM ds_ar_dhs.snap_individual GROUP BY ssn, file_month HAVING COUNT(*) > 10)
    GROUP BY sec.case_unit_id, si.SSN, sec.year_qtr_key
),
cteSNAP (social_security_number, program_name, year_qtr_key, state_abbreviation, Enrolled_Entire_Quarter,
         Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter,
         Gross_Monthly_Income, Net_Monthly_Income)
AS
(
    SELECT DISTINCT
            --LOOKUP VALUE FOR PERSON KEY
            cteSNAPIncome.social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Supplemental Nutrition Assistance Program (SNAP)' AS VARCHAR(75)) AS program_name,
            --OBSERVATION YEAR QUARTER KEY
            cteSNAPIncome.year_qtr_key,
            --LOOKUP VALUE FOR STATE KEY
            snap.state AS state_abbreviation,
            --Measures
            CASE
                WHEN cteSNAPIncome.qtr_first_month = 'Yes' AND cteSNAPIncome.qtr_second_month = 'Yes' AND cteSNAPIncome.qtr_third_month = 'Yes' THEN 'Yes'
                ELSE 'No'
            END AS Enrolled_Entire_Quarter,
            cteSNAPIncome.qtr_first_month AS Enrolled_First_Month_of_Quarter,
            cteSNAPIncome.qtr_second_month AS Enrolled_Second_Month_of_Quarter,
            cteSNAPIncome.qtr_third_month AS Enrolled_Third_Month_of_Quarter,
            CAST(cteSNAPIncome.gross_monthly_income AS DECIMAL(14,2)) AS Gross_Monthly_Income,
            CAST(cteSNAPIncome.net_monthly_income AS DECIMAL(14,2)) AS Net_Monthly_Income
    FROM cteSNAPIncome
    INNER JOIN ds_ar_dhs.snap_individual snap
        ON cteSNAPIncome.case_unit_id = snap.case_unit_id
        AND cteSNAPIncome.social_security_number = snap.ssn
        AND cteSNAPIncome.file_month = snap.file_month
    WHERE DATEPART(YEAR, snap.file_month) >= 2010
),
cteFactData (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2,
             Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = snap.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = snap.program_name
            ) AS Program_Key,
            --Observation Year Quarter Surrogate Key
            snap.year_qtr_key AS Observation_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,   -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = snap.state_abbreviation
            ) AS State_of_Residence_Key,    -- source data does not contain state of residence
            --CIP Surrogate Key
            0 AS CIP_Classification_Key,    -- source data does not contain CIP Classification
            --Measures
            snap.Enrolled_Entire_Quarter,
            snap.Enrolled_First_Month_of_Quarter,
            snap.Enrolled_Second_Month_of_Quarter,
            snap.Enrolled_Third_Month_of_Quarter,
            snap.Gross_Monthly_Income AS Gross_Monthly_Income,
            snap.Net_Monthly_Income AS Net_Monthly_Income,
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            CAST('' AS CHAR(1)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            CAST('' AS CHAR(1)) AS Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM cteSNAP snap
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Observation_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

TANF

/*
  This script will load the the FACT_Person_Program_Observation_Quarter table with data for the "Temporary Assistance for Needy Families (TANF)" program.
    Step 1
        Get a list of exit records for each ssn and observation quarter.
        The observation quarter is calculated from the reporting_month.
        The results are returned in the cteTANFQuarter common table expression (CTE).
    Step 2
        Collect data for each record in cteTANFQuarter.
        The results are returned in the cteTANF CTE.
    Step 3
        Lookup the dimension keys for each cteTANF record.
        The results are returned in the cteFactData CTE.
    Step 4
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Observation Quarter (TANF)
INSERT INTO FACT_Person_Program_Observation_Quarter (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key,
                                                     CIP_Classification_Key, Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter,
                                                     Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter, Gross_Monthly_Income, Net_Monthly_Income,
                                                     Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
                                                     Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
                                                     Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
                                                     Participated_in_Postsecondary_Education_During_Program_Participation, 
                                                     Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                                     Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                                     Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
                                                     Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
                                                     Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
WITH cteTANFQuarter (social_security_number, year_qtr_key, qtr_first_month, qtr_second_month, qtr_third_month, reporting_month)
AS
(
    SELECT  tanf_member.social_security_number,
            qtr.Year_Quarter_Key,
            MAX(CASE WHEN RIGHT(tanf_member.reporting_month, 2) IN ('01', '04', '07', '10') THEN 'Yes' ELSE 'No' END) AS qtr_first_month,
            MAX(CASE WHEN RIGHT(tanf_member.reporting_month, 2) IN ('02', '05', '08', '11') THEN 'Yes' ELSE 'No' END) AS qtr_second_month,
            MAX(CASE WHEN RIGHT(tanf_member.reporting_month, 2) IN ('03', '06', '09', '12') THEN 'Yes' ELSE 'No' END) AS qtr_third_month,
            MIN(tanf_member.reporting_month)
    FROM ds_ar_dhs.tanf_member
    INNER JOIN DIM_Year_Quarter qtr
        ON TO_DATE(CONCAT(tanf_member.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD') BETWEEN qtr.Quarter_Start_Date AND qtr.Quarter_End_Date
    WHERE LEFT(tanf_member.reporting_month, 4) >= '2010'
    AND LEN(tanf_member.reporting_month) = 6
    AND tanf_member.valid_ssn_format = 'Y'
    GROUP BY tanf_member.social_security_number, qtr.Year_Quarter_Key
),
cteTANF (social_security_number, program_name, year_qtr_key, state_fips_code, Enrolled_Entire_Quarter,
         Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
AS
(
    SELECT DISTINCT
            --LOOKUP VALUE FOR PERSON KEY
            tanf_member.social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Temporary Assistance for Needy Families (TANF)' AS VARCHAR(75)) AS program_name,
            --OBSERVATION YEAR QUARTER KEY
            cteTANFQuarter.year_qtr_key,
            --LOOKUP VALUE FOR STATE KEY
            tanf_member.state_fips_code,
            --Measures
            CASE
                WHEN cteTANFQuarter.qtr_first_month = 'Yes' AND cteTANFQuarter.qtr_second_month = 'Yes' AND cteTANFQuarter.qtr_third_month = 'Yes' THEN 'Yes'
                ELSE 'No'
            END AS Enrolled_Entire_Quarter,
            cteTANFQuarter.qtr_first_month AS Enrolled_First_Month_of_Quarter,
            cteTANFQuarter.qtr_second_month AS Enrolled_Second_Month_of_Quarter,
            cteTANFQuarter.qtr_third_month AS Enrolled_Third_Month_of_Quarter
    FROM cteTANFQuarter
    INNER JOIN ds_ar_dhs.tanf_member
        ON cteTANFQuarter.social_security_number = tanf_member.social_security_number
        AND cteTANFQuarter.reporting_month = tanf_member.reporting_month
    WHERE LEFT(tanf_member.reporting_month, 4) >= '2010'
    AND LEN(tanf_member.reporting_month) = 6
    AND tanf_member.valid_ssn_format = 'Y'
),
cteFactData (Person_Key, Program_Key, Observation_Year_Quarter_Key, County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key,
             Enrolled_Entire_Quarter, Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter,
             Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name,
             Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
             Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
             Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = tanf.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = tanf.program_name
            ) AS Program_Key,
            --Observation Year Quarter Surrogate Key
            tanf.year_qtr_key AS Observation_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,   -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_FIPS_Code = tanf.state_fips_code
            ) AS State_of_Residence_Key,    -- source data does not contain state of residence
            --CIP Surrogate Key
            0 AS CIP_Classification_Key,    -- source data does not contain CIP Classification
            --Measures
            tanf.Enrolled_Entire_Quarter,
            tanf.Enrolled_First_Month_of_Quarter,
            tanf.Enrolled_Second_Month_of_Quarter,
            tanf.Enrolled_Third_Month_of_Quarter,
            0 AS Gross_Monthly_Income,      -- source data does not contain gross monthly income
            0 AS Net_Monthly_Income,        -- source data does not contain net monthly income
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            CAST('' AS CHAR(1)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            CAST('' AS CHAR(1)) AS Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            CAST('' AS CHAR(1)) AS Higher_Education_Student_Level,
            CAST('' AS CHAR(1)) AS Higher_Education_Enrollment_Status,
            CAST('' AS CHAR(1)) AS Higher_Education_Tuition_Status
    FROM cteTANF tanf
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Observation_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Enrolled_Entire_Quarter,
        Enrolled_First_Month_of_Quarter,
        Enrolled_Second_Month_of_Quarter,
        Enrolled_Third_Month_of_Quarter,
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

FACT Person Program Participation Tables

Higher Education

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Higher Education" program.
    Step 1
        Try to remove duplicated higher education records by grouping on ssn, entry quarter, and exit quarter and selecting
            the minium academic_year and miniumum term for each grouping.
        The entry and exit quarters are calculated using academic_year and term.  Academic_year has to be adjusted to calendar year. 
    Step 2
        Collect data for each record found in step 1.
        The results are returned in the cteHigherEducation CTE.
    Step 3
        Lookup the dimension keys for each cteHigherEducation record.
        The results are returned in the cteFactData CTE.
    Step 4
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (Higher Education)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH cteDeDuplicate (social_security_number, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, academic_year, academic_term)
AS
(
    SELECT  se.ssn_id AS social_security_number,
            entry_qtr.Year_Quarter_Key AS Entry_Year_Quarter_Key,
            exit_qtr.Year_Quarter_Key AS Exit_Year_Quarter_Key,
            MIN(se.academic_year),
            MIN(se.term) AS academic_term
    FROM ds_ar_dhe.student_enrollment_table se
    INNER JOIN DIM_Year_Quarter entry_qtr
        ON entry_qtr.calendar_year = CASE WHEN se.term IN ('1', '5') THEN CAST(CAST(se.academic_year AS INT) - 1 AS CHAR(4)) ELSE se.academic_year END
        AND entry_qtr.calendar_quarter = CASE WHEN se.term IN ('0', '4') THEN '3' WHEN se.term IN ('1', '5') THEN '3' WHEN se.term IN ('2', '6') THEN '1' WHEN se.term IN ('3', '7') THEN '2' END
    INNER JOIN DIM_Year_Quarter exit_qtr
        ON exit_qtr.calendar_year = CASE WHEN se.term IN ('1', '5') THEN CAST(CAST(se.academic_year AS INT) - 1 AS CHAR(4)) ELSE se.academic_year END
        AND exit_qtr.calendar_quarter = CASE WHEN se.term IN ('0', '4') THEN '3' WHEN se.term IN ('1', '5') THEN '4' WHEN se.term IN ('2', '6') THEN '2' WHEN se.term IN ('3', '7') THEN '2' END
    WHERE se.academic_year >= '2011'
    AND se.ssn_valid_format = 'Y'
    AND se.term IN ('0', '1', '2', '3', '4', '5', '6', '7')
    GROUP BY se.ssn_id, entry_qtr.Year_Quarter_Key, exit_qtr.Year_Quarter_Key
),
cteHigherEducation (social_security_number, program_name, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_FIPS_Code, state_abbreviation, cip_code, cip_detail,
                    Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
                    Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
                    Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
                    Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
                    Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry, 
                    Participated_in_Postsecondary_Education_During_Program_Participation, Enrolled_in_Secondary_Education_Program, 
                    Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  cteDeDuplicate.social_security_number,
            CAST('Higher Education' AS VARCHAR(75)) AS program_name,
            cteDeDuplicate.Entry_Year_Quarter_Key,
            cteDeDuplicate.Exit_Year_Quarter_Key,
            COALESCE(se.geo_county, '') AS County_FIPS_Code,
            COALESCE(se.geo_state, '') AS state_abbreviation,
            COALESCE(dfy.cip_code, '') AS cip_code,
            COALESCE(dfy.cip_detail, '') AS cip_detail,
            CASE
                WHEN se.student_level = '14' THEN '11'
                WHEN se.student_level = '13' THEN ''
                WHEN se.diploma_ged = 1 THEN ''
                ELSE '12'
            END AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE 
                WHEN se.student_level IN ('02','03','04') THEN 'Completed one of more years of postsecondary education'
                WHEN se.student_level IN ('05', '06', '10') THEN 'Attained a Bachelor degree'
                WHEN se.student_level IN ('07', '08', '09') THEN 'Attained a degree beyond a Bachelor degree'
                WHEN se.student_level IN ('13', '14') THEN ''
                WHEN se.diploma_ged = 1 THEN 'Attained a secondary school equivalency'
                ELSE 'Attained secondary school diploma'
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE
                WHEN se.student_level IN ('13', '14') THEN 'In-school, secondary school or less'
                WHEN se.student_level BETWEEN '01' AND '11' THEN 'In-school, Postsecondary school'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Employment_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Long_Term_Unemployment_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Foster_Care_Youth_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Homeless_or_Runaway_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Ex_Offender_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Income_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS English_Language_Learner_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Levels_of_Literacy_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Cultural_Barriers_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Single_Parent_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Displaced_Homemaker_at_Program_Entry,
            CAST('Yes' AS CHAR(3)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('Yes' AS CHAR(3)) AS Enrolled_in_Secondary_Education_Program,
            COALESCE(rsl.descr, '') AS Higher_Education_Student_Level,
            COALESCE(res.descr, '') AS Higher_Education_Enrollment_Status,
            COALESCE(rts.descr, '') AS Higher_Education_Tuition_Status
    FROM ds_ar_dhe.student_enrollment_table se
    INNER JOIN cteDeDuplicate
        ON se.ssn_id = cteDeDuplicate.social_security_number
        AND se.academic_year = cteDeDuplicate.academic_year
        and se.term = cteDeDuplicate.academic_term
    LEFT JOIN ds_ar_dhe.degree_fice_year_Table dfy
        ON se.fice_code = dfy.fice_code
        AND se.academic_year = dfy.academic_year
        AND se.major_1 = dfy.degree_code
    LEFT JOIN ds_ar_dhe.refenrollstatus res
        ON se.enroll_status = res.enrollstatusid
    LEFT JOIN ds_ar_dhe.refstudentlevel rsl
        ON se.student_level = rsl.countryid     -- note: The name of the PK for this table is probably a typo (i.e. incorrect)
    LEFT JOIN ds_ar_dhe.reftuitionstatus rts
        ON se.tuition_status = rts.tuitionstatusid
    WHERE se.academic_year >= '2011'
    AND se.ssn_valid_format = 'Y'
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence,
             Higher_Education_Student_Level, Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = he.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE he.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND he.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND he.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND he.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND he.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND he.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND he.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND he.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND he.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND he.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND he.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND he.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND he.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND he.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND he.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = he.program_name
            ) AS Program_Key,
            --Entry Year Quarter Surrogate Key
            he.Entry_Year_Quarter_Key,
            --Exit Year Quarter Surrogate Key
            he.Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = he.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = he.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = CONCAT(he.cip_code, CONCAT(CAST('.' AS CHAR(1)), he.cip_detail))
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            he.Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            he.Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Incarcerated_at_Program_Entry,
            CAST('9999-01-01' AS DATE) AS Date_Released_from_Incarceration,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            he.Higher_Education_Student_Level,
            he.Higher_Education_Enrollment_Status,
            he.Higher_Education_Tuition_Status
    FROM cteHigherEducation he
)
SELECT DISTINCT
        COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status, 
        Higher_Education_Tuition_Status
FROM cteFactData;

JOINT PIRL

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Adult Education (JOINT)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.jointpirl_raw_data) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (JOINT PIRL)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, state_abbreviation, cip_code, Highest_School_Grade_Completed_at_Program_Entry,
              Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry, Employment_Status_at_Program_Entry,
              Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry, Foster_Care_Youth_Status_at_Program_Entry,
              Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry, Low_Income_Status_at_Program_Entry,
              English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry, Cultural_Barriers_at_Program_Entry,
              Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry, Date_of_Most_Recent_Career_Service, Received_Training,
              Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1,
              Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3,
              Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
              Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement,
              Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
              Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult Education (JOINT)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa AS entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CAST('9999-01-01' AS DATE),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CAST('9999-01-01' AS DATE),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END
    FROM ds_ar_dws.jointpirl_raw_data
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND ssn_valid_format = 1
    AND adult_education_wioa = 1
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date between entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,  -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,     -- source data does not contain gross monthly income
            0 AS Net_Monthly_Income,       -- source data does not contain net monthly income
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            CAST('' AS VARCHAR(5)) AS Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Adult Education

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Adult Education (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - adult education)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult Education (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND adult_education_wioa = 1
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Adult

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Adult (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - adult)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Adult (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND adult_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Dislocated Worker

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Dislocated Worker (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - dislocated worker)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Dislocated Worker (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND dislocated_worker_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Job Corps

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Job Corps (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - job corps)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Job Corps (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND job_corps_wioa = 1
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL Vocational Rehab

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Vocational Rehabilitation (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - vocational rehab)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Vocational Rehabilitation (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND vocational_rehabilitation_wioa IN (1, 2, 3)
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL Wagner Peyser

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Wagner-Peyser Employment Service (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - wagner peyser)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Wagner-Peyser Employment Service (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND wagner_peyser_employment_service_wioa = 1
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Youth Build

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "YouthBuild (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - youth build)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('YouthBuild (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youthbuild_wioa IS NOT NULL
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

PIRL - Youth

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "YouthBuild (WIOA)" program.
  Step 1
    The data is collected from the source table (ds_ar_dws.pirl) and returned in the ctePIRL comment table expression (CTE).
    Any reference values or boolean values are converted to text strings.
  Step 2
    The ctePirl data is then process thru the cteFactData CTE which looks up the dimension keys.
  Step 3
    The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (PIRL - youth build)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH ctePirl (social_security_number, program_name, entry_date, exit_date, County_FIPS_Code, state_abbreviation, cip_code,
              Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
              Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
              Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
              Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
              Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
              Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study,
              Date_Entered_Training_1, Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2,
              Date_Entered_Training_3, Type_of_Training_Service_3, Participated_in_Postsecondary_Education_During_Program_Participation,
              Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program,
              Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, Youth_4th_Quarter_Placement,
              Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status,
              Individual_with_a_Disability, Zip_Code_of_Residence)
AS
(
    SELECT  --LOOKUP VALUE FOR PERSON KEY
            social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('YouthBuild (WIOA)' AS VARCHAR(75)) AS program_name,
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            date_of_program_entry_wioa as entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            COALESCE(date_of_program_exit_wioa, CAST('9999-12-31' AS DATE)) AS exit_date,
            --LOOKUP VALUES FOR COUNTY KEY
            CASE
                WHEN LEN(RTRIM(county_code_of_residence)) = 3 AND states.State_FIPS_Code IS NOT NULL
                    THEN CAST(CONCAT(states.State_FIPS_Code, county_code_of_residence) AS VARCHAR(5))
                ELSE ''
            END AS County_FIPS_Code,
            --LOOKUP VALUE FOR STATE KEY
            COALESCE(state_code_of_residence_wioa, '') AS state_abbreviation,
            --LOOKUP VALUE FOR CIP KEY
            COALESCE(eligible_training_provider_cip_code_wioa, '') AS cip_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            COALESCE(highest_school_grade_completed_at_program_entry_wioa, '') AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE highest_educational_level_completed_at_program_entry_wioa
                WHEN '1' THEN 'Attained secondary school diploma'
                WHEN '2' THEN 'Attained a secondary school equivalency'
                WHEN '3' THEN 'Successfully completed an Individualized Education Program (IEP)'
                WHEN '4' THEN 'Completed one of more years of postsecondary education'
                WHEN '5' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '6' THEN 'Attained an Associate degree'
                WHEN '7' THEN 'Attained a Bachelor degree'
                WHEN '8' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '0' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CASE school_status_at_program_entry_wioa
                WHEN '1' THEN 'In-school, secondary school or less'
                WHEN '2' THEN 'In-school, Alternative School'
                WHEN '3' THEN 'In-school, Postsecondary school'
                WHEN '4' THEN 'Not attending school or Secondary School Dropout'
                WHEN '5' THEN 'Not attending school; secondary school graduate or has a recognized equivalent'
                WHEN '6' THEN 'Not attending school; within age of compulsory school attendance'
                ELSE ''
            END AS School_Status_at_Program_Entry,
            CASE employment_status_at_program_entry_wioa
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed, but Received Notice of Termination of Employment or Military Separation is pending'
                WHEN '3' THEN 'Not in labor force'
                WHEN '0' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CASE long_term_unemployed_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Long_Term_Unemployment_at_Program_Entry,
            CASE exhausting_tanf_within_2_years_part_a_title_iv_of_the_social_security_act_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE foster_care_youth_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CASE homeless_participant_homeless_children_and_youths_or_runaway_youth_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Homeless_or_Runaway_at_Program_Entry,
            CASE ex_offender_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Ex_Offender_Status_at_Program_Entry,
            CASE low_income_status_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Income_Status_at_Program_Entry,
            CASE english_language_learner_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS English_Language_Learner_at_Program_Entry,
            CASE basic_skills_deficient_low_levels_of_literacy_at_program_entry
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Low_Levels_of_Literacy_at_Program_Entry,
            CASE cultural_barriers_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Cultural_Barriers_at_Program_Entry,
            CASE single_parent_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Single_Parent_at_Program_Entry,
            CASE displaced_homemaker_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            COALESCE(date_of_most_recent_career_service_wioa, CAST('9999-01-01' AS DATE)),
            CASE received_training_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(eligible_training_provider_name_training_service_1_wioa, ''),
            CASE eligible_training_provider_program_of_study_by_potential_outcome
                WHEN '1' THEN 'A program of study leading to an industry-recognized certificate or certification'
                WHEN '2' THEN 'A program of study leading to a certificate of completion of a registered apprenticeship'
                WHEN '3' THEN 'A program of study leading to a license recognized by the State involved or the Federal Government'
                WHEN '4' THEN 'A program of study leading to an associate degree'
                WHEN '5' THEN 'A program of study leading to a baccalaureate degree'
                WHEN '6' THEN 'A program of study leading to a community college certificate of completion'
                WHEN '7' THEN 'A program of study leading to a secondary school diploma or its equivalent'
                WHEN '8' THEN 'A program of study leading to employment'
                WHEN '9' THEN 'A program of study leading to  a measurable skills gain'
                ELSE ''
            END,
            COALESCE(date_entered_training_1_wioa, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_1_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_2, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_2_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            COALESCE(date_entered_training_3, CAST('9999-01-01' AS DATE)),
            CASE type_of_training_service_3_wioa
                WHEN '01' THEN 'On the Job Training (non-WIOA Youth).'
                WHEN '02' THEN 'Skill Upgrading'
                WHEN '03' THEN 'Entrepreneurial Training (non-WIOA Youth)'
                WHEN '04' THEN 'ABE or ESL (contextualized or other) in conjunction with Training'
                WHEN '05' THEN 'Customized Training'
                WHEN '06' THEN 'Occupational Skills Training (non-WIOA Youth)'
                WHEN '07' THEN 'ABE or ESL NOT in conjunction with training (funded by Trade Adjustment Assistance only)'
                WHEN '08' THEN 'Prerequisite Training'
                WHEN '09' THEN 'Registered Apprenticeship '
                WHEN '10' THEN 'Youth Occupational Skills Training                                                                                                            '
                WHEN '11' THEN 'Other Non-Occupational-Skills Training   '
                WHEN '12' THEN 'Job Readiness Training in conjunction with other training                                                   '
                WHEN '00' THEN 'No Training Service'
                ELSE ''
            END,
            CASE participated_in_postsecondary_education_during_program_participation_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE received_training_from_programs_operated_by_the_private_sector
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE enrolled_in_secondary_education_program_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_enrolled_in_post_exit_education_or_training_program_leading_to_a_recognized_postsecondary_credential_wioa, CAST('9999-01-01' AS DATE)),
            CASE youth_2nd_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE youth_4th_quarter_placement_title_i_wioa
                WHEN '1' THEN 'Occupational Skills Training'
                WHEN '2' THEN 'Postsecondary Education'
                WHEN '3' THEN 'Secondary Education'
                WHEN '0' THEN 'No placement'
                ELSE ''
            END,
            CASE incarcerated_at_program_entry_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(date_released_from_incarceration_wioa, CAST('9999-01-01' AS DATE)),
            CASE other_reasons_for_exit_wioa
                WHEN '01' THEN 'Institutionalized'
                WHEN '02' THEN 'Health/Medical'
                WHEN '03' THEN 'Deceased'
                WHEN '05' THEN 'Foster Care'
                WHEN '06' THEN 'Ineligible'
                WHEN '07' THEN 'Criminal Offender'
                WHEN '00' THEN 'No'
                ELSE ''
            END,
            CASE migrant_and_seasonal_farmworker_status
                WHEN '1' THEN 'Seasonal Farmworker Adult'
                WHEN '2' THEN 'Migrant Farmworker Adult'
                WHEN '3' THEN 'MSFW Youth'
                WHEN '4' THEN 'Dependent Adult'
                WHEN '5' THEN 'Dependent Youth'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            CASE individual_with_a_disability_wioa
                WHEN '1' THEN 'Yes'
                WHEN '0' THEN 'No'
                ELSE ''
            END,
            COALESCE(zip_code_of_residence, '')
    FROM ds_ar_dws.pirl
    LEFT JOIN DIM_State states
        ON pirl.state_code_of_residence_wioa = states.state_abbreviation
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youthbuild_wioa IS NOT NULL
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = pirl.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE pirl.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND pirl.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND pirl.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND pirl.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND pirl.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND pirl.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND pirl.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND pirl.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND pirl.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND pirl.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND pirl.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND pirl.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND pirl.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND pirl.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND pirl.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = pirl.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE pirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE pirl.exit_date BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --Lookup County Surrogate Key
            (
                SELECT DIM_County.County_Key
                FROM DIM_County
                WHERE DIM_County.County_FIPS_Code = pirl.County_FIPS_Code
            ) AS County_of_Residence_Key,
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = pirl.state_abbreviation
            ) AS State_of_Residence_Key,
            --Lookup CIP Surrogate Key
            (
                SELECT DIM_CIP.CIP_Key
                FROM DIM_CIP
                WHERE DIM_CIP.Classification_Code = pirl.cip_code
            ) AS CIP_Classification_Key,
            --Measures
            0 AS Gross_Monthly_Income,
            0 AS Net_Monthly_Income,
            pirl.Date_of_Most_Recent_Career_Service,
            pirl.Received_Training,
            pirl.Eligible_Training_Provider_Name,
            pirl.Eligible_Training_Provider_Program_of_Study,
            pirl.Date_Entered_Training_1,
            pirl.Type_of_Training_Service_1,
            pirl.Date_Entered_Training_2,
            pirl.Type_of_Training_Service_2,
            pirl.Date_Entered_Training_3,
            pirl.Type_of_Training_Service_3,
            pirl.Participated_in_Postsecondary_Education_During_Program_Participation,
            pirl.Received_Training_from_Private_Section_Operated_Program,
            pirl.Enrolled_in_Secondary_Education_Program,
            pirl.Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            pirl.Youth_2nd_Quarter_Placement,
            pirl.Youth_4th_Quarter_Placement,
            pirl.Incarcerated_at_Program_Entry,
            pirl.Date_Released_from_Incarceration,
            pirl.Other_Reason_for_Exit,
            pirl.Migrant_and_Seasonal_Farmworker_Status,
            pirl.Individual_with_a_Disability,
            pirl.Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM ctePirl pirl
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

SNAP

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Supplemental Nutrition Assistance Program (SNAP)" program.
    Step 1
        Find unique eligible cases and associate each unique case with a entry quarter and an exit quarter.
        The cert_start_date is used to determine the entry quarter and the cert_end_date is used to determine the exit quarter.
        The results are returned in the cteSNAPEligibleCase common table expression (CTE).
    Step 2
        Sum gross_monthly_income and net_monthly_income grouping on case, ssn, start quarter and exit quarter.
        The results are returned in the cteSNAPIncome CTE.
    Step 3
        Collect data for each case found in step 1 and supplement that data with the aggregated income values from step 2.
        The results are returned in the cteSNAP CTE.
    Step 4
        Lookup the dimension keys for eacn cteSNap record.
        The results are returned in the cteFactData CTE.
    Step 5
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (SNAP)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH cteSNAPEligibleCase (case_unit_id, entry_quarter_key, exit_quarter_key, entry_file_date, exit_file_date)
AS
(
    SELECT  snap_case.case_unit_id,
            entry_qtr.Year_Quarter_Key,
            exit_qtr.Year_Quarter_Key,
            MIN(file_month),
            MAX(file_month)
    FROM ds_ar_dhs.snap_case
    INNER JOIN DIM_Year_Quarter entry_qtr
        ON snap_case.cert_start_date BETWEEN entry_qtr.Quarter_Start_Date AND entry_qtr.Quarter_End_Date
    INNER JOIN DIM_Year_Quarter exit_qtr
        ON snap_case.cert_end_date BETWEEN exit_qtr.Quarter_Start_Date AND exit_qtr.Quarter_End_Date
    WHERE DATEPART(YEAR, snap_case.file_month) >= 2010
    AND DATEPART(YEAR, snap_case.cert_end_date) >= 2010
    AND snap_case.snap_eligibility = 1
    AND snap_case.file_month BETWEEN snap_case.cert_start_date AND snap_case.cert_end_date
    GROUP BY snap_case.case_unit_id, entry_qtr.Year_Quarter_Key, exit_qtr.Year_Quarter_Key
),
cteSNAPIncome (case_unit_id, social_security_number, entry_quarter_key, exit_quarter_key, gross_monthly_income, net_monthly_income, file_month)
AS
(
    SELECT  sec.case_unit_id,
            si.SSN,
            sec.entry_quarter_key,
            sec.exit_quarter_key,
            SUM(CASE WHEN si.gross_income_mo_indicator = 1 THEN si.gross_income_mo ELSE 0 END) AS gross_monthly_income,
            SUM(CASE WHEN si.net_income_mo_indicator = 1 THEN si.net_income_mo ELSE 0 END) AS net_monthly_income,
            MIN(si.file_month)
    FROM cteSNAPEligibleCase sec
    INNER JOIN ds_ar_dhs.snap_individual si
        ON sec.case_unit_id = si.case_unit_id
        AND si.file_month BETWEEN sec.entry_file_date AND sec.exit_file_date
    WHERE si.valid_ssn_format = 1
    AND si.ssn NOT IN (SELECT DISTINCT ssn FROM ds_ar_dhs.snap_individual GROUP BY ssn, file_month HAVING COUNT(*) > 10)
    GROUP BY sec.case_unit_id, si.SSN, sec.entry_quarter_key, sec.exit_quarter_key
),
cteSNAP (social_security_number, program_name, entry_quarter_key, exit_quarter_key, state_abbreviation,
         Highest_School_Grade_Completed_at_Program_Entry, Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
         Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
         Foster_Care_Youth_Status_at_Program_Entry, Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry,
         Low_Income_Status_at_Program_Entry, English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
         Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry,
         Gross_Monthly_Income, Net_Monthly_Income)
AS
(
    SELECT DISTINCT
            --LOOKUP VALUE FOR PERSON KEY
            cteSNAPIncome.social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Supplemental Nutrition Assistance Program (SNAP)' AS VARCHAR(75)) AS program_name,
            --ENTRY YEAR QUARTER KEY
            cteSNAPIncome.entry_quarter_key,
            --EXIT YEAR QUARTER KEY
            cteSNAPIncome.exit_quarter_key,
            --LOOKUP VALUE FOR STATE KEY
            snap.state AS state_abbreviation,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            CASE
                WHEN snap.highest_ed = '1' THEN '0'
                WHEN snap.highest_ed = '1G' THEN '1'
                WHEN snap.highest_ed = '2G' THEN '2'
                WHEN snap.highest_ed = '3G' THEN '3'
                WHEN snap.highest_ed = '4G' THEN '4'
                WHEN snap.highest_ed = '5G' THEN '5'
                WHEN snap.highest_ed = '6G' THEN '6'
                WHEN snap.highest_ed = '7G' THEN '7'
                WHEN snap.highest_ed = '8G' THEN '8'
                WHEN snap.highest_ed = '9G' THEN '9'
                WHEN snap.highest_ed = '10G' THEN '10'
                WHEN snap.highest_ed = '11G' THEN '11'
                WHEN snap.highest_ed IN ('12G', '13', '14', '15', '16', '17', '18', '19', '20', '21') THEN '12'
                ELSE ''
            END AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE snap.highest_ed
                WHEN '13' THEN 'Attained secondary school diploma'
                WHEN '14' THEN 'Attained a secondary school equivalency'
                WHEN '16' THEN 'Completed one of more years of postsecondary education'
                WHEN '17' THEN 'Attained an Associate degree'
                WHEN '18' THEN 'Attained a Bachelor degree'
                WHEN '19' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '20' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '21' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '1' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CAST('' AS CHAR(1)) AS School_Status_at_Program_Entry,
            CASE snap.employment
                WHEN '1' THEN 'Employed'
                WHEN '2' THEN 'Employed'
                WHEN '3' THEN 'Employed'
                WHEN '6' THEN 'Not in labor force'
                WHEN '4' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Long_Term_Unemployment_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CASE
                WHEN snap.relationship = '01' and snap.rel_child = '4' THEN 'Yes'
                WHEN snap.relationship = '01' and snap.rel_child IN ('1', '2', '3') THEN 'No'
                WHEN snap.relationship IN ('00', '02', '03', '04', '05', '06', '07') then 'No'
                ELSE ''
            END AS Foster_Care_Youth_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Homeless_or_Runaway_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Ex_Offender_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Income_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS English_Language_Learner_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Levels_of_Literacy_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Cultural_Barriers_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Single_Parent_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Displaced_Homemaker_at_Program_Entry,
            --FACT MEASURES
            CAST(cteSNAPIncome.gross_monthly_income AS DECIMAL(14,2)) AS Gross_Monthly_Income,
            CAST(cteSNAPIncome.net_monthly_income AS DECIMAL(14,2)) AS Net_Monthly_Income
    FROM cteSNAPIncome
    INNER JOIN ds_ar_dhs.snap_individual snap
        ON cteSNAPIncome.case_unit_id = snap.case_unit_id
        AND cteSNAPIncome.social_security_number = snap.ssn
        AND cteSNAPIncome.file_month = snap.file_month
    WHERE DATEPART(YEAR, snap.file_month) >= 2010
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = snap.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE snap.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND snap.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND snap.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND snap.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND snap.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND snap.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND snap.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND snap.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND snap.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND snap.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND snap.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND snap.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND snap.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND snap.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND snap.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = snap.program_name
            ) AS Program_Key,
            --Entry Year Quarter Surrogate Key
            snap.entry_quarter_key AS Entry_Year_Quarter_Key,
            --Exit Year Quarter Surrogate Key
            snap.exit_quarter_key AS Exit_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,   -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_Abbreviation = snap.state_abbreviation
            ) AS State_of_Residence_Key,
            --CIP Surrogate Key
            0 AS CIP_Classification_Key,    -- source data does not contain CIP Classification
            --Measures
            snap.Gross_Monthly_Income AS Gross_Monthly_Income,
            snap.Net_Monthly_Income AS Net_Monthly_Income,
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            CAST('' AS CHAR(1)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            CAST('' AS CHAR(1)) AS Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Incarcerated_at_Program_Entry,
            CAST('9999-01-01' AS DATE) AS Date_Released_from_Incarceration,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM cteSNAP snap
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

TANF

/*
  This script will load the the FACT_Person_Program_Participation table with data for the "Temporary Assistance for Needy Families (TANF)" program.
    Step 1
        Get a list of exit records for each ssn and reporting_month.
        Exit record will have tanf_end_of_spell = 'TRUE'.
        We only want the records that have tanf_start_of_spell = 'FALSE' in this step.
        The results are returned in the cteSpellEnd common table expression (CTE).
    Step 2
        Calculate TANF spells for each person by looking for record that have tanf_start_of_spell = 'TRUE'.
        Records that have tanf_end_of_spell = 'FALSE' will be matched to the nearest exit data from Step 1.
        Records that have tanf_end_of_spell = 'TRUE' will use the tanf_end_of_spell as the exit date.
        The results are returned in the cteTANFSpell CTE.
    Step 3
        Collect data for each case found in step 2.
        The results are returned in the cteTANF CTE.
    Step 4
        Lookup the dimension keys for each cteTANF record.
        The results are returned in the cteFactData CTE.
    Step 5
        The cteFactData is inserted into the fact table.  Any keys that could not be found via the lookup are set to 0.
*/

-- FACT Person Program Participation (TANF)
INSERT INTO FACT_Person_Program_Participation (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key,
                                               County_of_Residence_Key, State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, 
                                               Net_Monthly_Income, Date_of_Most_Recent_Career_Service, Received_Training, Eligible_Training_Provider_Name, 
                                               Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1, Type_of_Training_Service_1, 
                                               Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
                                               Participated_in_Postsecondary_Education_During_Program_Participation, 
                                               Received_Training_from_Private_Section_Operated_Program, Enrolled_in_Secondary_Education_Program, 
                                               Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
                                               Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, 
                                               Other_Reason_for_Exit, Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability,
                                               Zip_Code_of_Residence, Higher_Education_Student_Level, Higher_Education_Enrollment_Status, 
                                               Higher_Education_Tuition_Status)
WITH cteSpellEnd (social_security_number, reporting_month)
AS
(
    SELECT DISTINCT social_security_number, reporting_month
    FROM ds_ar_dhs.tanf_member
    WHERE tanf_start_of_spell = 'FALSE'
    AND tanf_end_of_spell = 'TRUE'
    AND LEFT(reporting_month, 4) >= '2010'
    AND LEN(tanf_member.reporting_month) = 6
    AND valid_ssn_format = 'Y'
),
cteTANFSpell (social_security_number, entry_date, exit_date)
AS
(
    SELECT  ts.social_security_number,
            TO_DATE(CONCAT(ts.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD'),
            CASE
                WHEN MIN(cteSpellEnd.reporting_month) IS NULL THEN TO_DATE('9999-01-01', 'YYYYMMDD')
                ELSE TO_DATE(CONCAT(MIN(cteSpellEnd.reporting_month), CAST('01' AS CHAR(2))), 'YYYYMMDD')
            END
    FROM ds_ar_dhs.tanf_member ts
    LEFT JOIN cteSpellEnd
        ON ts.social_security_number = cteSpellEnd.social_security_number
        AND ts.reporting_month < cteSpellEnd.reporting_month
    WHERE ts.tanf_start_of_spell = 'TRUE'
    AND ts.tanf_end_of_spell = 'FALSE'
    AND LEFT(ts.reporting_month, 4) >= '2010'
    AND LEN(ts.reporting_month) = 6
    AND ts.valid_ssn_format = 'Y'
    GROUP BY ts.social_security_number, ts.reporting_month
    UNION 
    SELECT  tm.social_security_number,
            TO_DATE(CONCAT(tm.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD'),
            TO_DATE(CONCAT(tm.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD')
    FROM ds_ar_dhs.tanf_member tm
    WHERE tm.tanf_start_of_spell = 'TRUE'
    AND tm.tanf_end_of_spell = 'TRUE'
    AND LEFT(tm.reporting_month, 4) >= '2010'
    AND LEN(tm.reporting_month) = 6
    AND tm.valid_ssn_format = 'Y'
),
cteTANF (social_security_number, program_name, entry_date, exit_date, state_fips_code, Highest_School_Grade_Completed_at_Program_Entry,
         Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry, Employment_Status_at_Program_Entry,
         Long_Term_Unemployment_at_Program_Entry, Exhausting_TANF_Within_2_Yrs_at_Program_Entry, Foster_Care_Youth_Status_at_Program_Entry,
         Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry, Low_Income_Status_at_Program_Entry,
         English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry, Cultural_Barriers_at_Program_Entry,
         Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry)
AS
(
    SELECT DISTINCT
            --LOOKUP VALUE FOR PERSON KEY
            cteTANFSpell.social_security_number,
            --LOOKUP VALUE FOR PROGRAM KEY
            CAST('Temporary Assistance for Needy Families (TANF)' AS VARCHAR(75)),
            --LOOKUP VALUE FOR ENTRY YEAR QUARTER KEY
            cteTANFSpell.entry_date,
            --LOOKUP VALUE FOR EXIT YEAR QUARTER KEY
            cteTANFSpell.exit_date,
            --LOOKUP VALUE FOR STATE KEY
            tanf_member.state_fips_code,
            --LOOKUP VALUES FOR INTAKE CHARACTERISTICS KEY
            CASE
                WHEN education_level IN ('01', '02', '03', '04', '05', '06', '07', '08', '09', '10', '11', '12') THEN education_level
                WHEN education_level IN ('13', '14', '15', '16') THEN '12'
                WHEN education_level = '98' THEN '0'
                ELSE ''
            END AS Highest_School_Grade_Completed_at_Program_Entry,
            CASE education_level
                WHEN '12' THEN 'Attained secondary school diploma'
                WHEN '16' THEN 'Attained a postsecondary technical or vocational certificate (non-degree)'
                WHEN '13' THEN 'Attained an Associate degree'
                WHEN '14' THEN 'Attained a Bachelor degree'
                WHEN '15' THEN 'Attained a degree beyond a Bachelor degree'
                WHEN '98' THEN 'No Educational Level Completed'
                ELSE ''
            END AS Highest_Education_Level_Completed_at_Program_Entry,
            CAST('' AS CHAR(1)) AS School_Status_at_Program_Entry,
            CASE employment_status
                WHEN '1' THEN 'Employed'
                WHEN '3' THEN 'Not in labor force'
                WHEN '2' THEN 'Unemployed'
                ELSE ''
            END AS Employment_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Long_Term_Unemployment_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Foster_Care_Youth_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Homeless_or_Runaway_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Ex_Offender_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Income_Status_at_Program_Entry,
            CAST('' AS CHAR(1)) AS English_Language_Learner_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Low_Levels_of_Literacy_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Cultural_Barriers_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Single_Parent_at_Program_Entry,
            CAST('' AS CHAR(1)) AS Displaced_Homemaker_at_Program_Entry
    FROM cteTANFSpell
    INNER JOIN ds_ar_dhs.tanf_member
        ON cteTANFSpell.social_security_number = tanf_member.social_security_number
        AND cteTANFSpell.entry_date = TO_DATE(CONCAT(tanf_member.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD')
    WHERE tanf_member.tanf_start_of_spell = 'TRUE'
    AND LEFT(tanf_member.reporting_month, 4) >= '2010'
    AND LEN(tanf_member.reporting_month) = 6
),
cteFactData (Person_Key, Intake_Characteristics_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key, County_of_Residence_Key,
             State_of_Residence_Key, CIP_Classification_Key, Gross_Monthly_Income, Net_Monthly_Income, Date_of_Most_Recent_Career_Service,
             Received_Training, Eligible_Training_Provider_Name, Eligible_Training_Provider_Program_of_Study, Date_Entered_Training_1,
             Type_of_Training_Service_1, Date_Entered_Training_2, Type_of_Training_Service_2, Date_Entered_Training_3, Type_of_Training_Service_3, 
             Participated_in_Postsecondary_Education_During_Program_Participation, Received_Training_from_Private_Section_Operated_Program,
             Enrolled_in_Secondary_Education_Program, Date_Enrolled_in_Post_Exit_Education_or_Training_Program, Youth_2nd_Quarter_Placement, 
             Youth_4th_Quarter_Placement, Incarcerated_at_Program_Entry, Date_Released_from_Incarceration, Other_Reason_for_Exit,
             Migrant_and_Seasonal_Farmworker_Status, Individual_with_a_Disability, Zip_Code_of_Residence, Higher_Education_Student_Level,
             Higher_Education_Enrollment_Status, Higher_Education_Tuition_Status)
AS
(
    SELECT  --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = tanf.social_security_number
            ) AS Person_Key,
            --Lookup Intake Characteristics Surrogate Key
            (
                SELECT DIM_Intake_Characteristics.Intake_Characteristics_Key
                FROM DIM_Intake_Characteristics
                WHERE tanf.Highest_School_Grade_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_School_Grade_Completed_at_Program_Entry
                AND tanf.Highest_Education_Level_Completed_at_Program_Entry = DIM_Intake_Characteristics.Highest_Education_Level_Completed_at_Program_Entry
                AND tanf.School_Status_at_Program_Entry = DIM_Intake_Characteristics.School_Status_at_Program_Entry
                AND tanf.Employment_Status_at_Program_Entry = DIM_Intake_Characteristics.Employment_Status_at_Program_Entry
                AND tanf.Long_Term_Unemployment_at_Program_Entry = DIM_Intake_Characteristics.Long_Term_Unemployment_at_Program_Entry
                AND tanf.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = DIM_Intake_Characteristics.Exhausting_TANF_Within_2_Yrs_at_Program_Entry
                AND tanf.Foster_Care_Youth_Status_at_Program_Entry = DIM_Intake_Characteristics.Foster_Care_Youth_Status_at_Program_Entry
                AND tanf.Homeless_or_Runaway_at_Program_Entry = DIM_Intake_Characteristics.Homeless_or_Runaway_at_Program_Entry
                AND tanf.Ex_Offender_Status_at_Program_Entry = DIM_Intake_Characteristics.Ex_Offender_Status_at_Program_Entry
                AND tanf.Low_Income_Status_at_Program_Entry = DIM_Intake_Characteristics.Low_Income_Status_at_Program_Entry
                AND tanf.English_Language_Learner_at_Program_Entry = DIM_Intake_Characteristics.English_Language_Learner_at_Program_Entry
                AND tanf.Low_Levels_of_Literacy_at_Program_Entry = DIM_Intake_Characteristics.Low_Levels_of_Literacy_at_Program_Entry
                AND tanf.Cultural_Barriers_at_Program_Entry = DIM_Intake_Characteristics.Cultural_Barriers_at_Program_Entry
                AND tanf.Single_Parent_at_Program_Entry = DIM_Intake_Characteristics.Single_Parent_at_Program_Entry
                AND tanf.Displaced_Homemaker_at_Program_Entry = DIM_Intake_Characteristics.Displaced_Homemaker_at_Program_Entry
            ) AS Intake_Characteristics_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = tanf.program_name
            ) AS Program_Key,
            --Lookup Entry Year Quarter Surrogate Key
            (
                SELECT entry_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter entry_qtr
                WHERE tanf.entry_date between entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date      
            ) AS Entry_Year_Quarter_Key,
            --Lookup Exit Year Quarter Surrogate Key
            (
                SELECT exit_qtr.Year_Quarter_Key
                FROM DIM_Year_Quarter exit_qtr
                WHERE tanf.exit_date between exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
            ) AS Exit_Year_Quarter_Key,
            --County Surrogate Key
            0 AS County_of_Residence_Key,   -- source data does not contain county of residence
            --Lookup State Surrogate Key
            (
                SELECT DIM_State.State_Key
                FROM DIM_State
                WHERE DIM_State.State_FIPS_Code = tanf.state_fips_code
            ) AS State_of_Residence_Key,    -- source data does not contain state of residence
            --CIP Surrogate Key
            0 AS CIP_Classification_Key,    -- source data does not contain CIP Classification
            --Measures
            0 AS Gross_Monthly_Income,      -- source data does not contain gross monthly income
            0 AS Net_Monthly_Income,        -- source data does not contain net monthly income
            CAST('9999-01-01' AS DATE) AS Date_of_Most_Recent_Career_Service,
            CAST('' AS CHAR(1)) AS Received_Training,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Name,
            CAST('' AS CHAR(1)) AS Eligible_Training_Provider_Program_of_Study,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_1,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_1,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_2,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_2,
            CAST('9999-01-01' AS DATE) AS Date_Entered_Training_3,
            CAST('' AS CHAR(1)) AS Type_of_Training_Service_3,
            CAST('' AS CHAR(1)) AS Participated_in_Postsecondary_Education_During_Program_Participation,
            CAST('' AS CHAR(1)) AS Received_Training_from_Private_Section_Operated_Program,
            CAST('' AS CHAR(1)) AS Enrolled_in_Secondary_Education_Program,
            CAST('9999-01-01' AS DATE) AS Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
            CAST('' AS CHAR(1)) AS Youth_2nd_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Youth_4th_Quarter_Placement,
            CAST('' AS CHAR(1)) AS Incarcerated_at_Program_Entry,
            CAST('9999-01-01' AS DATE) AS Date_Released_from_Incarceration,
            CAST('' AS CHAR(1)) AS Other_Reason_for_Exit,
            CAST('' AS CHAR(1)) AS Migrant_and_Seasonal_Farmworker_Status,
            CAST('' AS CHAR(1)) AS Individual_with_a_Disability,
            CAST('' AS CHAR(1)) AS Zip_Code_of_Residence,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Student_Level,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Enrollment_Status,
            CAST('' AS VARCHAR(100)) AS Higher_Education_Tuition_Status
    FROM cteTANF tanf
)
SELECT  COALESCE(Person_Key, 0),
        COALESCE(Intake_Characteristics_Key, 0),
        COALESCE(Program_Key, 0),
        COALESCE(Entry_Year_Quarter_Key, 0),
        COALESCE(Exit_Year_Quarter_Key, 0),
        COALESCE(County_of_Residence_Key, 0),
        COALESCE(State_of_Residence_Key, 0),
        COALESCE(CIP_Classification_Key, 0),
        Gross_Monthly_Income,
        Net_Monthly_Income,
        Date_of_Most_Recent_Career_Service,
        Received_Training,
        Eligible_Training_Provider_Name,
        Eligible_Training_Provider_Program_of_Study,
        Date_Entered_Training_1,
        Type_of_Training_Service_1,
        Date_Entered_Training_2,
        Type_of_Training_Service_2,
        Date_Entered_Training_3,
        Type_of_Training_Service_3,
        Participated_in_Postsecondary_Education_During_Program_Participation,
        Received_Training_from_Private_Section_Operated_Program,
        Enrolled_in_Secondary_Education_Program,
        Date_Enrolled_in_Post_Exit_Education_or_Training_Program,
        Youth_2nd_Quarter_Placement,
        Youth_4th_Quarter_Placement,
        Incarcerated_at_Program_Entry,
        Date_Released_from_Incarceration,
        Other_Reason_for_Exit,
        Migrant_and_Seasonal_Farmworker_Status,
        Individual_with_a_Disability,
        Zip_Code_of_Residence,
        Higher_Education_Student_Level,
        Higher_Education_Enrollment_Status,
        Higher_Education_Tuition_Status
FROM cteFactData;

FACT Person Quarterly Program Enrollment Tables

JOINT PIRL

/*
This script will load the FACT Person Quarterly Program Enrollment table with data for the "Adult Education (JOINT)" program.
    Step 1
        People with program enrollments in the source table (ds_ar_dws.jointpirl_raw_data) are returned in the ctePIRL comment table expression (CTE).
        Redundancy in the source data requires grouping  the enrollments for an individual and program entry date in order to determine
        the correct program exit date.  The program exit date can be null is some situation and any null dates are converted to the 
        current date in step 2.
        The results of this step are returned in the ctePIRL common table expression (CTE).
    Step 2
        The entry and exit dates in the ctePIRL CTE are converted to an entry quarter and an exit quarter.  If the exit date is null then
        the current date is used as the exit date.
        The results of this step are returned in the cteQuarterRange CTE.
    Step 3
        This step looks up the dimension keys for the person and program and expands the results to include every quarter between the entry
        quarter and exit quarter (inclusive).  The minimm entry date or maximum exit date are used to calculate the
        Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, and Enrolled_Third_Month_of_Quarter indicators for the first
        and last quarters in the enrollment period.  All quarters between the entry and exit are assumed to include all months in the quarter.
        The results will include all quarters for each enrollment period a person might have.
        The results of this step are returned in the cteFactData CTE.
    Step 4
        The value of the Enrolled_Entire_Quarter indicator is calculated and the results inserted into the fact table.
*/

-- FACT Person Quarterly Program Enrollment (Joint PIRL)
INSERT INTO FACT_Person_Quarterly_Program_Enrollment (Person_Key, Program_Key, Enrollment_Quarter_Key, Enrolled_Entire_Quarter,
                                                      Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
WITH ctePirl (social_security_number, entry_date, exit_date)
AS
(
    SELECT social_security_number, date_of_program_entry_wioa, MAX(date_of_program_exit_wioa)
    FROM ds_ar_dws.jointpirl_raw_data
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND ssn_valid_format = 1
    AND adult_education_wioa = 1
    GROUP BY social_security_number, date_of_program_entry_wioa
),
cteQuarterRange (social_security_number, entry_quarter_key, exit_quarter_key, min_entry_date, max_exit_date)
AS
(
    SELECT  ctePirl.social_security_number,
            entry_qtr.Year_Quarter_Key AS entry_quarter_key,
            exit_qtr.Year_Quarter_Key AS exit_quarter_key,
            MIN(ctePirl.entry_date) AS min_entry_date,
            MAX(COALESCE(ctePirl.exit_date, GETDATE())) AS max_exit_date
    FROM ctePirl
    INNER JOIN DIM_Year_Quarter entry_qtr
        ON ctePirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date     
    INNER JOIN DIM_Year_Quarter exit_qtr
        ON COALESCE(ctePirl.exit_date, GETDATE()) BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
    GROUP BY ctePirl.social_security_number, entry_qtr.Year_Quarter_Key, exit_qtr.Year_Quarter_Key
),
cteFactData (Person_Key, Program_Key, Enrollment_Year_Quarter_Key, Enrolled_First_Month_of_Quarter,
             Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
AS
(
    SELECT DISTINCT
            --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = cteQuarterRange.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = 'Adult Education (JOINT)'
            ) AS Program_Key,
            qtr.Year_Quarter_Key,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.entry_quarter_key AND DATEPART(MONTH, cteQuarterRange.min_entry_date) NOT IN (1, 4, 7, 10) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Enrolled_First_Month_of_QuarterEntire_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.entry_quarter_key AND DATEPART(MONTH, cteQuarterRange.min_entry_date) IN (3, 6, 9, 12) THEN CAST('No' AS VARCHAR(3))
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.exit_quarter_key AND DATEPART(MONTH, cteQuarterRange.max_exit_date) IN (1, 4, 7, 10) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.exit_quarter_key AND DATEPART(MONTH, cteQuarterRange.max_exit_date) NOT IN (3, 6, 9, 12) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Third_Month_of_Quarter
    FROM cteQuarterRange
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteQuarterRange.entry_quarter_key AND cteQuarterRange.exit_quarter_key
)
SELECT  Person_Key,
        Program_Key,
        Enrollment_Year_Quarter_Key,
        CASE
            WHEN MAX(Enrolled_First_Month_of_Quarter) = 'Yes' AND MAX(Enrolled_Second_Month_of_Quarter) = 'Yes' AND MAX(Enrolled_Third_Month_of_Quarter) = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        MAX(Enrolled_First_Month_of_Quarter),
        MAX(Enrolled_Second_Month_of_Quarter),
        MAX(Enrolled_Third_Month_of_Quarter)
FROM cteFactData
GROUP BY Person_Key, Program_Key, Enrollment_Year_Quarter_Key;

PIRL

/*
This script will load the FACT Person Quarterly Program Enrollment table with data for the PIRL (WIOA) programs.  This will include the
following programs:  Adult Education (WIOA),  Adult (WIOA), Dislocated Worker (WIOA), Job Corps (WIOA), Vocational Rehabilitation (WIOA),
                     Wagner-Peyser Employment Service (WIOA), Youth (WIOA), YouthBuild (WIOA)
    Step 1
        People with program enrollments in the source table (ds_ar_dws.pirl) are returned in the ctePIRL comment table expression (CTE).
        All of the programs enrollments are pull seperately and then unioned together. Redundancy in the source data requires grouping
        the enrollments for an individual and program entry date in order to determine the correct program exit date.  The program exit
        date can be null is some situation and any null dates are converted to the current date in step 2.
        The results of this step are returned in the ctePIRL common table expression (CTE).
    Step 2
        The entry and exit dates in the ctePIRL CTE are converted to an entry quarter and an exit quarter.  If the exit date is null then
        the current date is used as the exit date.
        The results of this step are returned in the cteQuarterRange CTE.
    Step 3
        This step looks up the dimension keys for the person and program and expands the results to include every quarter between the entry
        quarter and exit quarter (inclusive).  The minimm entry date or maximum exit date are used to calculate the
        Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, and Enrolled_Third_Month_of_Quarter indicators for the first
        and last quarters in the enrollment period.  All quarters between the entry and exit are assumed to include all months in the quarter.
        The results will include all quarters for each enrollment period a person might have.
        The results of this step are returned in the cteFactData CTE.
    Step 4
        The value of the Enrolled_Entire_Quarter indicator is calculated and the results inserted into the fact table.
*/

-- FACT Person Quarterly Program Enrollment (PIRL - adult education)
INSERT INTO FACT_Person_Quarterly_Program_Enrollment (Person_Key, Program_Key, Enrollment_Quarter_Key, Enrolled_Entire_Quarter,
                                                      Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
WITH ctePirl (program_name, social_security_number, entry_date, exit_date)
AS
(
    --Adult Education
    SELECT  CAST('Adult Education (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa AS entry_date,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND adult_education_wioa = 1
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    -- Adult
    SELECT  CAST('Adult (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND adult_wioa IN (1, 2, 3)
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --Dislocated Worker
    SELECT  CAST('Dislocated Worker (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND dislocated_worker_wioa IN (1, 2, 3)
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --Job Corps
    SELECT  CAST('Job Corps (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND job_corps_wioa = 1
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --Vocational Rehabilitation
    SELECT  CAST('Vocational Rehabilitation (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND vocational_rehabilitation_wioa IN (1, 2, 3)
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --Wagner-Peyser Employment Service
    SELECT  CAST('Wagner-Peyser Employment Service (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND wagner_peyser_employment_service_wioa = 1
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --Youth
    SELECT  CAST('Youth (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youth_wioa IN (1, 2, 3)
    GROUP BY social_security_number, date_of_program_entry_wioa
    UNION
    --YouthBuild
    SELECT  CAST('YouthBuild (WIOA)' AS VARCHAR(75)) AS program_name,
            social_security_number,
            date_of_program_entry_wioa,
            MAX(date_of_program_exit_wioa) AS exit_date
    FROM ds_ar_dws.pirl
    WHERE DATEPART(year, date_of_program_entry_wioa) >= 2010
    AND valid_ssn_format = 'Y'
    AND youthbuild_wioa IS NOT NULL
    GROUP BY social_security_number, date_of_program_entry_wioa
),
cteQuarterRange (program_name, social_security_number, entry_quarter_key, exit_quarter_key, min_entry_date, max_exit_date)
AS
(
    SELECT  ctePirl.program_name,
            ctePirl.social_security_number,
            entry_qtr.Year_Quarter_Key,
            exit_qtr.Year_Quarter_Key,
            MIN(ctePirl.entry_date) AS min_entry_date,
            MAX(COALESCE(ctePirl.exit_date, GETDATE())) AS max_exit_date
    FROM ctePirl
    INNER JOIN DIM_Year_Quarter entry_qtr
        ON ctePirl.entry_date BETWEEN entry_qtr.quarter_start_date AND entry_qtr.quarter_end_date     
    INNER JOIN DIM_Year_Quarter exit_qtr
        ON COALESCE(ctePirl.exit_date, GETDATE()) BETWEEN exit_qtr.quarter_start_date and exit_qtr.quarter_end_date
    GROUP BY ctePirl.program_name, ctePirl.social_security_number, entry_qtr.Year_Quarter_Key, exit_qtr.Year_Quarter_Key
),
cteFactData (Person_Key, Program_Key, Enrollment_Year_Quarter_Key, Enrolled_First_Month_of_Quarter,
             Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
AS
(
    SELECT DISTINCT
            --Lookup Person Surrogate Key
            (
                SELECT DIM_Person.Person_Key
                FROM DIM_Person
                WHERE DIM_Person.Person_UID = cteQuarterRange.social_security_number
            ) AS Person_Key,
            --Lookup Program Surrogate Key
            (
                SELECT DIM_Program.Program_Key
                FROM DIM_Program
                WHERE DIM_Program.Program_Name = cteQuarterRange.program_name
            ) AS Program_Key,
            qtr.Year_Quarter_Key,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.entry_quarter_key AND DATEPART(MONTH, cteQuarterRange.min_entry_date) NOT IN (1, 4, 7, 10) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Enrolled_First_Month_of_QuarterEntire_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.entry_quarter_key AND DATEPART(MONTH, cteQuarterRange.min_entry_date) IN (3, 6, 9, 12) THEN CAST('No' AS VARCHAR(3))
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.exit_quarter_key AND DATEPART(MONTH, cteQuarterRange.max_exit_date) IN (1, 4, 7, 10) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Second_Month_of_Quarter,
            CASE
                WHEN qtr.Year_Quarter_Key = cteQuarterRange.exit_quarter_key AND DATEPART(MONTH, cteQuarterRange.max_exit_date) NOT IN (3, 6, 9, 12) THEN CAST('No' AS VARCHAR(3))
                ELSE CAST('Yes' AS VARCHAR(3))
            END AS Enrolled_Third_Month_of_Quarter
    FROM cteQuarterRange
    INNER JOIN DIM_Year_Quarter qtr
        ON qtr.Year_Quarter_Key BETWEEN cteQuarterRange.entry_quarter_key AND cteQuarterRange.exit_quarter_key
)
SELECT  Person_Key,
        Program_Key,
        Enrollment_Year_Quarter_Key,
        CASE
            WHEN MAX(Enrolled_First_Month_of_Quarter) = 'Yes' AND MAX(Enrolled_Second_Month_of_Quarter) = 'Yes' AND MAX(Enrolled_Third_Month_of_Quarter) = 'Yes' THEN 'Yes'
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        MAX(Enrolled_First_Month_of_Quarter),
        MAX(Enrolled_Second_Month_of_Quarter),
        MAX(Enrolled_Third_Month_of_Quarter)
FROM cteFactData
GROUP BY Person_Key, Program_Key, Enrollment_Year_Quarter_Key;

SNAP

/*
This script will load the FACT Person Quarterly Program Enrollment table with data for the "Supplemental Nutrition Assistance Program (SNAP)" program.
    Step 1
        Find file months were people had enrollments in the source tables (ds_ar_dhs.snap_case, ds_ar_dhs.snap_individual).
        The file month's must be within the cert range of an eligible case to be included.
        The results of this step are returned in the cteFileMonths common table expression (CTE).
    Step 2
        File months are mapped to their corresponding quarter and a qtr_month_flag is created to identify which months in the quarter were enrolled.
        The qtr_month_flag is the decimal representation of a binary number where each bit in the binary represents a month.  The first (left most) bit is
        used to represent the first month of the quarter and the third (right most) bit is used for the third month.  The results are grouped on person
        and quarter and the binary month flags are summed together to create the qtr_month_flag which will have a decimal value between
        1 (binary 001) and 7 (binary 111).
        The results are returned in the cteSNAP CTE which should contain one record for each person and quarter that had an enrollment.
    Step 3
        This step looks up the dimension keys for the person and program.  The qtr_month_flag is used to calculate the Enrolled_Entire_Quarter, 
        Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, and Enrolled_Third_Month_of_Quarter indicators.  The results will include
        all quarters for each enrollment period a person might have.
        The results of this step are inserted into the fact table..
*/

-- FACT Person Quarterly Program Enrollment (SNAP)
INSERT INTO FACT_Person_Quarterly_Program_Enrollment (Person_Key, Program_Key, Enrollment_Quarter_Key, Enrolled_Entire_Quarter,
                                                      Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
WITH cteFileMonths (social_security_number, file_month)
AS
(
    SELECT DISTINCT snap_individual.SSN, snap_case.file_month
    FROM ds_ar_dhs.snap_case
    INNER JOIN ds_ar_dhs.snap_individual
        ON snap_case.case_unit_id = snap_individual.case_unit_id
        AND snap_case.file_month = snap_individual.file_month
    WHERE snap_case.snap_eligibility = 1
    AND DATEPART(YEAR, snap_case.file_month) >= 2010
    AND snap_case.file_month BETWEEN snap_case.cert_start_date AND snap_case.cert_end_date
    AND snap_individual.valid_ssn_format = 1
),
cteSNAP (social_security_number, Enrollment_Quarter_Key, qtr_month_flag)
AS
(
    SELECT  cteFileMonths.social_security_number,
            qtr.Year_Quarter_Key,
            --Decimal representation of a binary flag where the 1st, 2nd, and 3rd month of the quarter are identified as separate bits and added together to create a bitmask.
            --Example 1: If only enrolled in the 2nd month of the quarter, then the 2nd bit will be turned on. [010 (binary) equals 2 (decimal)]
            --Example 2: If enrolled in the 2nd and 3rd months of the quarter, then the 2nd and 3rd bits will be turned on.  [010 + 100 = 110 (binary) equals 6 (decimal)]
            SUM(CASE
                    WHEN DATEPART(MONTH, cteFileMonths.file_month) IN (1, 4, 7, 10) THEN 1  --equals 001 binary
                    WHEN DATEPART(MONTH, cteFileMonths.file_month) IN (2, 5, 8, 11) THEN 2  --equals 010 binary
                    WHEN DATEPART(MONTH, cteFileMonths.file_month) IN (3, 6, 9, 12) THEN 4  --equals 100 binary
                END) AS qtr_month_flag
    FROM cteFileMonths
    INNER JOIN DIM_Year_Quarter qtr
        ON cteFileMonths.file_month BETWEEN qtr.Quarter_Start_Date and qtr.Quarter_End_Date
    GROUP BY cteFileMonths.social_security_number, qtr.Year_Quarter_Key
)
SELECT DISTINCT
        --Lookup Person Surrogate Key
        (
            SELECT DIM_Person.Person_Key
            FROM DIM_Person
            WHERE DIM_Person.Person_UID = cteSNAP.social_security_number
        ) AS Person_Key,
        --Lookup Program Surrogate Key
        (
            SELECT DIM_Program.Program_Key
            FROM DIM_Program
            WHERE DIM_Program.Program_Name = 'Supplemental Nutrition Assistance Program (SNAP)'
        ) AS Program_Key,
        cteSNAP.Enrollment_Quarter_Key,
        CASE
            WHEN qtr_month_flag = 7 THEN 'Yes'  --[001 + 010 + 100 = 111 (binary) equals 7 (decimal)]
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        CASE
            WHEN qtr_month_flag IN (1, 3, 5, 7) THEN 'Yes'  --If the first bit is on, then the 1st month had an enrollment. (001, 011, 101, 111)
            ELSE 'No'
        END AS Enrolled_First_Month_of_Quarter,
        CASE
            WHEN qtr_month_flag IN (2, 3, 6, 7) THEN 'Yes'  --If the second bit is on, then the 2nd month had an enrollment. (010, 011, 110, 111)
            ELSE 'No'
        END AS Enrolled_Second_Month_of_Quarter,
        CASE
            WHEN qtr_month_flag IN (4, 5, 6, 7) THEN 'Yes'  --If the third bit is on, then the 3rd month had an enrollment. (100, 101, 110, 111)
            ELSE 'No'
        END AS Enrolled_Third_Month_of_Quarter
FROM cteSNAP;

TANF

/*
This script will load the FACT Person Quarterly Program Enrollment table with data for the "Temporary Assistance for Needy Families (TANF)" program.
    Step 1
        Find reporting months that only have a spell end record.
        Data is returned in the cteSpellEnd common table expression (CTE).
    Step 2
        Find spell start and end months for each person.  If a record has both the start_of_spell and end_of_spell flags set to true then the entry and exit months
        are set to the reporting_month.  If the record only has start_of_spell set to true, then the nearest reporting_month for the same person in cteSpellEnd is used
        as the exit month.  Note that if there are two or more overlapping spell ranges with different end months, then one or more of the spells could have the wrong end month.
        The results of this step are returned in the cteTANFSpell CTE.
    Step 3
        Reporting months are mapped to their corresponding quarter and a qtr_month_flag is created to identify which months in the quarter were enrolled.
        The qtr_month_flag is the decimal representation of a binary number where each bit in the binary represents a month.  The first (left most) bit is
        used to represent the first month of the quarter and the third (right most) bit is used for the third month.  The results are grouped on person
        and quarter and the binary month flags are summed together to create the qtr_month_flag which will have a decimal value between
        1 (binary 001) and 7 (binary 111).
        The results are returned in the cteTANF CTE which should contain one record for each person and quarter that had an enrollment.
    Step 4
        This step looks up the dimension keys for the person and program.  The qtr_month_flag is used to calculate the Enrolled_Entire_Quarter, 
        Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, and Enrolled_Third_Month_of_Quarter indicators.  The results will include
        all quarters for each enrollment period a person might have.
        The results of this step are inserted into the fact table..
*/

-- FACT Person Quarterly Program Enrollment (TANF)
INSERT INTO FACT_Person_Quarterly_Program_Enrollment (Person_Key, Program_Key, Enrollment_Quarter_Key, Enrolled_Entire_Quarter,
                                                      Enrolled_First_Month_of_Quarter, Enrolled_Second_Month_of_Quarter, Enrolled_Third_Month_of_Quarter)
WITH cteSpellEnd (social_security_number, reporting_month)
AS
(
    --If the start of spell flag is off and the end of spell flag is on, then the reporting month is when the spell ended.
    --These end of spell reporting months will be matched to spell starts in the cteTANFSpell query below. 
    SELECT DISTINCT social_security_number, reporting_month
    FROM ds_ar_dhs.tanf_member
    WHERE tanf_start_of_spell = 'FALSE'
    AND tanf_end_of_spell = 'TRUE'
    AND LEFT(reporting_month, 4) >= '2010'
    AND LEN(tanf_member.reporting_month) = 6
    AND valid_ssn_format = 'Y'
),
cteTANFSpell (social_security_number, entry_month, exit_month)
AS
(
    -- If the start and end of spell flags are both turned on, then the entry and exit months are the reporting month.
    SELECT  tm.social_security_number, tm.reporting_month, tm.reporting_month
    FROM ds_ar_dhs.tanf_member tm
    WHERE tm.tanf_start_of_spell = 'TRUE'
    AND tm.tanf_end_of_spell = 'TRUE'
    AND LEFT(tm.reporting_month, 4) >= '2010'
    AND LEN(tm.reporting_month) = 6
    AND tm.valid_ssn_format = 'Y'
    UNION
    --If the start of spell flag is on and the end of spell flag is off, then we have to find the nearest spell end in cteSpellEnd.
    --WARNING: If there are two overlapping spells with different end months for the same person, then one of the spells could end up using the wrong end date.
    --      Example 1: If spell #1 ran from February 2022 thru June 2022 and spell #2 ran from March 2022 thru September 2022 
    --                 then spell #1 will be correct but spell #2 will incorrectly end in June 2022 rather than September 2022
    --                    because June 2022 is the min date that is greater than March 2022.
    --      Example 2: If spell #1 ran from February 2022 thru September 2022 and spell #2 ran from March 2022 thru June 2022 
    --                 then spell #2 will be correct but spell #1 will incorrectly end in June 2022 rather than September 2022
    --                    because June 2022 is the min date that is greater than March 2022.
    SELECT  ts.social_security_number,
            ts.reporting_month,
            CASE
                WHEN MIN(cteSpellEnd.reporting_month) IS NULL THEN CAST('999901' AS CHAR(6))
                ELSE MIN(cteSpellEnd.reporting_month)
            END
    FROM ds_ar_dhs.tanf_member ts
    LEFT JOIN cteSpellEnd
        ON ts.social_security_number = cteSpellEnd.social_security_number
        AND ts.reporting_month < cteSpellEnd.reporting_month
    WHERE ts.tanf_start_of_spell = 'TRUE'
    AND ts.tanf_end_of_spell = 'FALSE'
    AND LEFT(ts.reporting_month, 4) >= '2010'
    AND LEN(ts.reporting_month) = 6
    AND ts.valid_ssn_format = 'Y'
    GROUP BY ts.social_security_number, ts.reporting_month
),
cteTANF (social_security_number, Enrollment_Quarter_Key, qtr_month_flag)
AS
(
    SELECT  cteTANFSpell.social_security_number,
            qtr.Year_Quarter_Key,
            --Decimal representation of a binary flag where the 1st, 2nd, and 3rd month of the quarter are identified as separate bits and added together to create a bitmask.
            --Example 1: If only enrolled in the 2nd month of the quarter, then the 2nd bit will be turned on. [010 (binary) equals 2 (decimal)]
            --Example 2: If enrolled in the 2nd and 3rd months of the quarter, then the 2nd and 3rd bits will be turned on.  [010 + 100 = 110 (binary) equals 6 (decimal)]
            SUM(CASE 
                    WHEN RIGHT(tanf_member.reporting_month, 2) IN ('01', '04', '07', '10') THEN 1  --equals 001 binary
                    WHEN RIGHT(tanf_member.reporting_month, 2) IN ('02', '05', '08', '11') THEN 2  --equals 010 binary
                    WHEN RIGHT(tanf_member.reporting_month, 2) IN ('03', '06', '09', '12') THEN 4  --equals 100 binary
                END) AS qtr_month_flag
    FROM cteTANFSpell
    INNER JOIN ds_ar_dhs.tanf_member
        ON tanf_member.reporting_month BETWEEN cteTANFSpell.entry_month AND cteTANFSpell.exit_month
    INNER JOIN DIM_Year_Quarter qtr
        ON TO_DATE(CONCAT(tanf_member.reporting_month, CAST('01' AS CHAR(2))), 'YYYYMMDD') BETWEEN qtr.Quarter_Start_Date and qtr.Quarter_End_Date
    GROUP BY cteTANFSpell.social_security_number, qtr.Year_Quarter_Key
)
SELECT DISTINCT
        --Lookup Person Surrogate Key
        (
            SELECT DIM_Person.Person_Key
            FROM DIM_Person
            WHERE DIM_Person.Person_UID = cteTANF.social_security_number
        ) AS Person_Key,
        --Lookup Program Surrogate Key
        (
            SELECT DIM_Program.Program_Key
            FROM DIM_Program
            WHERE DIM_Program.Program_Name = 'Temporary Assistance for Needy Families (TANF)'
        ) AS Program_Key,
        cteTANF.Enrollment_Quarter_Key,
        CASE
            WHEN qtr_month_flag = 7 THEN 'Yes'  --[001 + 010 + 100 = 111 (binary) equals 7 (decimal)]
            ELSE 'No'
        END AS Enrolled_Entire_Quarter,
        CASE
            WHEN qtr_month_flag IN (1, 3, 5, 7) THEN 'Yes'  --If the first bit is on, then the 1st month had an enrollment. (001, 011, 101, 111)
            ELSE 'No'
        END AS Enrolled_First_Month_of_Quarter,
        CASE
            WHEN qtr_month_flag IN (2, 3, 6, 7) THEN 'Yes'  --If the second bit is on, then the 2nd month had an enrollment. (010, 011, 110, 111)
            ELSE 'No'
        END AS Enrolled_Second_Month_of_Quarter,
        CASE
            WHEN qtr_month_flag IN (4, 5, 6, 7) THEN 'Yes'  --If the third bit is on, then the 3rd month had an enrollment. (100, 101, 110, 111)
            ELSE 'No'
        END AS Enrolled_Third_Month_of_Quarter
FROM cteTANF;

FACT Person UI Wage Table

UI Wage

-- FACT Person UI Wage
INSERT INTO FACT_Person_UI_Wage (Person_Key, Year_Quarter_Key, UI_Quarterly_Wages)
SELECT p.Person_Key, qtr.Year_Quarter_Key, sum(lehd.employee_wage_amount)
FROM ds_ar_dws.ui_wages_lehd lehd
INNER JOIN DIM_Person p
    ON lehd.employee_ssn = p.Person_UID
INNER JOIN DIM_Year_Quarter qtr
    ON lehd.reporting_period_year = qtr.Calendar_Year
    AND lehd.reporting_period_quarter = qtr.Calendar_Quarter
WHERE lehd.reporting_period_year >= '2010'
GROUP BY p.Person_Key, qtr.Year_Quarter_Key;

Dimension Tables

DIM CIP

-- Add "REDACTED" CIP dimension record (ONLY RUN ONCE)
/*
INSERT INTO DIM_CIP (CIP_Key, Classification_Code, Classification_Name, Category_Name,
                     Series_Name, Series_Short_Name, Major_Group_Code, Major_Group_Name)
VALUES (REDACTED, 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED');
*/


-- Add new CIP code dimension records
INSERT INTO DIM_CIP (CIP_Key, Classification_Code, Classification_Name, Category_Name,
                     Series_Name, Series_Short_Name, Major_Group_Code, Major_Group_Name)
SELECT  mdm.CIP_ID, mdm.Classification_Code, mdm.Classification_Name, mdm.Category_Name,
        mdm.Series_Name, mdm.Series_Short_Name, mdm.Major_Group_Code, mdm.Major_Group_Name
FROM MDM_CIP mdm
LEFT JOIN DIM_CIP dim
    ON mdm.CIP_ID = dim.CIP_Key
WHERE dim.CIP_Key IS NULL;

-- Update changed CIP code dimension records
UPDATE DIM_CIP
SET Classification_Name = mdm.Classification_Name
    Category_Name = mdm.Category_Name
    Series_Name = mdm.Series_Name
    Series_Short_Name = mdm.Series_Short_Name
    Major_Group_Code = mdm.Major_Group_Code
    Major_Group_Name = mdm.Major_Group_Name
FROM MDM_CIP mdm
INNER JOIN DIM_CIP dim
    ON mdm.CIP_ID = dim.CIP_Key
WHERE mdm.Classification_Name <> dim.Classification_Name
    OR mdm.Category_Name <> dim.Category_Name
    OR mdm.Series_Name <> dim.Series_Name
    OR mdm.Series_Short_Name <> dim.Series_Short_Name
    OR mdm.Major_Group_Code <> dim.Major_Group_Code
    OR mdm.Major_Group_Name <> dim.Major_Group_Name;

DIM COUNTRY

-- Add "REDACTED" county dimension record (ONLY RUN ONCE)
/*
INSERT INTO DIM_County (County_Key, County_FIPS_Code, County_Name, Rural_Urban_Continuum, Local_Workforce_Development_Area)
VALUES (REDACTED, 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED');
*/

-- Add new county dimension records
INSERT INTO DIM_County (County_Key, County_FIPS_Code, County_Name, Rural_Urban_Continuum, Local_Workforce_Development_Area)
SELECT  mdm.County_ID,
        mdm.County_FIPS_Code,
        mdm.County_Name,
        mdm.Rural_Urban_Continuum,
        mdm.Local_Workforce_Development_Area
FROM MDM_County mdm
LEFT JOIN DIM_County dim
    ON mdm.County_ID = dim.County_Key
WHERE dim.County_KEY IS NULL;

-- Update changed county dimension records
UPDATE DIM_County
SET County_Name = county.name,
    Rural_Urban_Continuum = ruc.name,
    Local_Workforce_Development_Area = county.local_workforce_development_area
FROM MDM_County mdm
INNER JOIN DIM_County dim
    ON mdm.County_ID = dim.County_Key
WHERE mdm.County_Name <> dim.County_Name
    OR mdm.Rural_Urban_Continuum <> dim.Rural_Urban_Continuum
    OR mdm.Local_Workforce_Development_Area <> dim.Local_Workforce_Development_Area;

DIM Intake Characteristics

-- Add "REDACTED" Intake Characteristics dimension record (ONLY RUN ONCE)
/*
INSERT INTO DIM_Intake_Characteristics (Intake_Characteristics_Key, Highest_School_Grade_Completed_at_Program_Entry,
                                Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
                                Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry,
                                Exhausting_TANF_Within_2_Yrs_at_Program_Entry, Foster_Care_Youth_Status_at_Program_Entry,
                                Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry, Low_Income_Status_at_Program_Entry,
                                English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
                                Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry)
VALUES (REDACTED, 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED');
*/

-- Add new Intake Characteristics records
INSERT INTO DIM_Intake_Characteristics (Intake_Characteristics_Key, Highest_School_Grade_Completed_at_Program_Entry,
                                Highest_Education_Level_Completed_at_Program_Entry, School_Status_at_Program_Entry,
                                Employment_Status_at_Program_Entry, Long_Term_Unemployment_at_Program_Entry,
                                Exhausting_TANF_Within_2_Yrs_at_Program_Entry, Foster_Care_Youth_Status_at_Program_Entry,
                                Homeless_or_Runaway_at_Program_Entry, Ex_Offender_Status_at_Program_Entry, Low_Income_Status_at_Program_Entry,
                                English_Language_Learner_at_Program_Entry, Low_Levels_of_Literacy_at_Program_Entry,
                                Cultural_Barriers_at_Program_Entry, Single_Parent_at_Program_Entry, Displaced_Homemaker_at_Program_Entry)
SELECT  mdm.Intake_Characteristics_Master_ID,
        mdm.Highest_School_Grade_Completed_at_Program_Entry,
        mdm.Highest_Education_Level_Completed_at_Program_Entry,
        mdm.School_Status_at_Program_Entry,
        mdm.Employment_Status_at_Program_Entry,
        mdm.Long_Term_Unemployment_at_Program_Entry,
        mdm.Exhausting_TANF_Within_2_Yrs_at_Program_Entry,
        mdm.Foster_Care_Youth_Status_at_Program_Entry,
        mdm.Homeless_or_Runaway_at_Program_Entry,
        mdm.Ex_Offender_Status_at_Program_Entry,
        mdm.Low_Income_Status_at_Program_Entry,
        mdm.English_Language_Learner_at_Program_Entry,
        mdm.Low_Levels_of_Literacy_at_Program_Entry,
        mdm.Cultural_Barriers_at_Program_Entry,
        mdm.Single_Parent_at_Program_Entry,
        mdm.Displaced_Homemaker_at_Program_Entry
FROM MDM_Intake_Characteristics_Master mdm
LEFT JOIN DIM_Intake_Characteristics dim
    ON mdm.Intake_Characteristics_Master_ID = dim.Intake_Characteristics_Key
WHERE dim.Intake_Characteristics_Key IS NULL
AND NOT(mdm.Highest_School_Grade_Completed_at_Program_Entry = ''
        AND mdm.Highest_Education_Level_Completed_at_Program_Entry = ''
        AND mdm.School_Status_at_Program_Entry = ''
        AND mdm.Employment_Status_at_Program_Entry = ''
        AND mdm.Long_Term_Unemployment_at_Program_Entry = ''
        AND mdm.Exhausting_TANF_Within_2_Yrs_at_Program_Entry = ''
        AND mdm.Foster_Care_Youth_Status_at_Program_Entry = ''
        AND mdm.Homeless_or_Runaway_at_Program_Entry = ''
        AND mdm.Ex_Offender_Status_at_Program_Entry = ''
        AND mdm.Low_Income_Status_at_Program_Entry = ''
        AND mdm.English_Language_Learner_at_Program_Entry = ''
        AND mdm.Low_Levels_of_Literacy_at_Program_Entry = ''
        AND mdm.Cultural_Barriers_at_Program_Entry = ''
        AND mdm.Single_Parent_at_Program_Entry = ''
        AND mdm.Displaced_Homemaker_at_Program_Entry = '');

DIM Person

-- Add "blank" person dimension record (ONLY RUN ONCE)
/*
INSERT INTO DIM_Person (Person_Key, Person_UID, Date_of_Birth, Gender, Ethnicity_American_Indian_or_Alaska_Native,
                              Ethnicity_Asian, Ethnicity_Black_or_African_American, Ethnicity_Hispanic_or_Latino,
                              Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander, Ethnicity_White, Ethnicity_Other)
VALUES (REDACTED, 'REDACTED', CAST('9999-01-01' AS DATE), 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED', 'REDACTED');
*/

-- Add new person dimension records
INSERT INTO DIM_Person (Person_Key, Person_UID, Date_of_Birth, Gender, Ethnicity_American_Indian_or_Alaska_Native,
                   Ethnicity_Asian, Ethnicity_Black_or_African_American, Ethnicity_Hispanic_or_Latino,
                   Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander, Ethnicity_White, Ethnicity_Other)
SELECT  mdm.Person_Master_ID,
        mdm.Person_UID,
        mdm.Date_of_Birth,
        mdm.Gender,
        mdm.Ethnicity_American_Indian_or_Alaska_Native,
        mdm.Ethnicity_Asian,
        mdm.Ethnicity_Black_or_African_American,
        mdm.Ethnicity_Hispanic_or_Latino,
        mdm.Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander,
        mdm.Ethnicity_White,
        mdm.Ethnicity_Other
FROM MDM_Person_Master mdm
LEFT JOIN DIM_Person dim
    ON mdm.Person_Master_ID = dim.Person_Key
WHERE dim.Person_Key IS NULL;

-- Update changed person dimension records
UPDATE DIM_Person
SET Date_of_Birth = mdm.Date_of_Birth,
    Gender = mdm.Gender,
    Ethnicity_American_Indian_or_Alaska_Native = mdm.Ethnicity_American_Indian_or_Alaska_Native,
    Ethnicity_Asian = mdm.Ethnicity_Asian,
    Ethnicity_Black_or_African_American = mdm.Ethnicity_Black_or_African_American,
    Ethnicity_Hispanic_or_Latino = mdm.Ethnicity_Hispanic_or_Latino,
    Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander = mdm.Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander,
    Ethnicity_White = mdm.Ethnicity_White,
    Ethnicity_Other = mdm.Ethnicity_Other
FROM MDM_Person_Master mdm
INNER JOIN DIM_Person dim
    ON mdm.Person_Master_ID = dim.Person_Key
WHERE (dim.Date_of_Birth <> mdm.Date_of_Birth
    OR dim.Gender <> mdm.Gender
    OR dim.Ethnicity_American_Indian_or_Alaska_Native <> mdm.Ethnicity_American_Indian_or_Alaska_Native
    OR dim.Ethnicity_Asian <> mdm.Ethnicity_Asian
    OR dim.Ethnicity_Black_or_African_American <> mdm.Ethnicity_Black_or_African_American
    OR dim.Ethnicity_Hispanic_or_Latino <> mdm.Ethnicity_Hispanic_or_Latino
    OR dim.Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander <> mdm.Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander
    OR dim.Ethnicity_White <> mdm.Ethnicity_White
    OR dim.Ethnicity_Other <> mdm.Ethnicity_Other);

DIM Program

-- Add new program dimension records
INSERT INTO DIM_Program (Program_Key, Program_Name)
SELECT  mdm.Program_ID,
        mdm.Program_Name
FROM MDM_Program mdm
LEFT JOIN DIM_Program dim
    ON mdm.Program_ID = dim.Program_Key
WHERE dim.Program_Key IS NULL;

DIM State

-- Add "blank" State dimension record (ONLY RUN ONCE)
/*
INSERT INTO DIM_State (State_Key, State_FIPS_Code, State_Abbreviation, State_Name)
VALUES (0, '', '', '');
*/

INSERT INTO DIM_State (State_Key, State_FIPS_Code, State_Abbreviation, State_Name)
SELECT mdm.State_ID, mdm.State_FIPS_Code, mdm.State_Abbreviation, mdm.State_Name
FROM MDM_State mdm
LEFT JOIN DIM_State dim
    ON mdm.State_ID = dim.State_Key
WHERE dim.State_Key IS NULL;

DIM Year Quarter

-- Add new year/quarter dimension records
INSERT INTO DIM_Year_Quarter (Year_Quarter_Key, Calendar_Year, Calendar_Quarter, Quarter_Start_Date, Quarter_End_Date)
SELECT  mdm.Year_Quarter_ID,
        mdm.Calendar_Year,
        mdm.Calendar_Quarter,
        mdm.Quarter_Start_Date,
        mdm.Quarter_End_Date
FROM MDM_Year_Quarter mdm
LEFT JOIN DIM_Year_Quarter dim
    ON mdm.Year_Quarter_ID = dim.Year_Quarter_Key
WHERE dim.Year_Quarter_Key IS NULL;

MDM Person Instance


-- Person Instance (SNAP)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT ssn, NVL2(dob, dob, '1900-01-01'), 
       case sex when 'M' then 'Male'
                when 'F' then 'Female'
                when 'U' then 'Unknown'
                when '99' then 'Missing'
                when '88' then 'NC'
                else ''
        end,
    CASE race_aian 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE race_asian 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE race_black 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE hispanic 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE race_nhpi
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE race_white 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    CASE race_other 
        WHEN '99' THEN 'MI'
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when '88' then 'NC'
    END,
    'SNAP'
FROM ds_ar_dhs.snap_individual;




-- Person Instance (Graduated Student)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT ssn_id, '1900-01-01', 
       case gender when 'M' then 'Male'
                when 'F' then 'Female'
                when 'U' then 'Unknown'
                else ''
        end,
    CASE amerind 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE asian 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE black 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE hispanic 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE hawaiian
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE white 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END, 'N/A',
    'Graduated STudent'
FROM ds_ar_dhe.graduated_student_table;

-- Person Instance (Registration table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT ssn_id, '1900-01-01', '','','','','','','','','Student Registration'
FROM ds_ar_dhe.registration_table;

-- Person Instance (UI Wages LEHD table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT employee_ssn, '1900-01-01', '','','','','','','','','UI Wages LEHD'
FROM ds_ar_dws.ui_wages_lehd;

-- Person Instance (Student Enrollment table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT ssn_id, (to_date(nvl2(date_of_birth, date_of_birth, '1900-01-01'), 'MMDDYYYY')), 
    case gender when 'M' then 'Male'
                when 'F' then 'Female'
                when 'U' then 'Unknown'
                when 'O' then 'Other'
                else ''
        end,
    CASE amerind 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE asian 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE black 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE hispanic 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE hawaiian
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END,
    CASE white 
        WHEN 'Y' THEN 'Yes'
        WHEN 'N' THEN 'No'
        when 'U' then 'UK'
    END, 'N/A','Student Enrollment'
FROM ds_ar_dhe.student_enrollment_table;


-- Person Instance (PIRL table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT social_security_number,nvl2(date_of_birth_wioa, date_of_birth_wioa, '1900-01-01'), 
    case sex_wioa when '1' then 'Male'
                when '2' then 'Female'
                when '9' then 'Unknown'
                else ''
        end,
    CASE american_indian_alaska_native_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE asian_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE black_african_american_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE ethnicity_hispanic_latino_wioa 
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE native_hawaiian_other_pacific_islander_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE white_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END, 'N/A','PIRL'
    FROM ds_ar_dws.pirl;

-- Person Instance (PROMIS table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT ssn, to_date(nvl2(birth_date, birth_date, '1900-01-01'), 'YYYYMMDD'), 
    case gender when '1' then 'Male'
                when '2' then 'Female'
                when '6' then 'Unknown'
        end,
    case race when '4' then 'Yes'
              else ''
    END,
    CASE race  WHEN '3' THEN 'Yes'
        else ''
    END,
    CASE race
        WHEN '2' THEN 'Yes'
        else ''
    END,
    CASE ethnicity 
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE race
        WHEN '5' THEN 'Yes'
        else ''
    END,
    CASE race
        WHEN '1' THEN 'Yes'
        else ''
    END, 
    case race 
        when '6' then '2+'
        when '9' then 'UK'
        else ''
        end,'PROMIS'
    FROM ds_ar_dws.promis ;

-- Person Instance (TANF table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT social_security_number, nvl2(date_of_birth , date_of_birth , '1900-01-01'), 
    case gender when '1' then 'Male'
                when '2' then 'Female'
                when '3' then 'Unknown'
        end,
    CASE ethnicity_american_indian_alaska_native
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END,
    CASE ethnicity_asian
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END,
    CASE ethnicity_black_african_american 
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END,
    CASE ethnicity_hispanic_latino
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END,
    CASE ethnicity_native_hawaiian_pacific_islander
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END,
    CASE ethnicity_white
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        else ''
    END, 
    'N/A','TANF'
    FROM ds_ar_dhs.tanf_member  ;

-- Person Instance (Joint PIRL table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT NVL2(social_security_number, social_security_number, '' ),nvl2(date_of_birth_wioa, date_of_birth_wioa, '1900-01-01'), 
    case sex_wioa when '1' then 'Male'
                when '2' then 'Female'
                when '9' then 'Unknown'
                when '3' then ''
        end,
    CASE american_indian_alaska_native_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END,
    CASE asian_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END,
    CASE black_african_american_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END,
    CASE ethnicity_hispanic_latino_wioa 
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END,
    CASE native_hawaiian_other_pacific_islander_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END,
    CASE white_wioa
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
    END, 'N/A','Joint PIRL'
    FROM ds_ar_dws.jointpirl_raw_data;

-- Person Instance (Rapids Apprentice table)
INSERT INTO tr_ar_wdqi_2023.mdm_person_instance (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, data_source)
SELECT nvl2(ssn, ssn, ''),nvl2(dob, dob, '1900-01-01'), 
    case gender when 'M' then 'Male'
                when 'F' then 'Female'
                when 'U' then 'Unknown'
                else ''
        end,
    CASE natindianind
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE asianind
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE africaamerind
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE ethnicind 
        WHEN '1' THEN 'Yes'
        WHEN '2' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE nathawaiind
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END,
    CASE wind
        WHEN '1' THEN 'Yes'
        WHEN '0' THEN 'No'
        when '9' then 'UK'
        else ''
    END, 'N/A','RAPIDS Apprentice'
    FROM ds_ar_osd.rapids_apprentice ;

MDM Person Master

--Person Master Load
INSERT INTO tr_ar_wdqi_2023.mdm_person_master (person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other)
select * from (
select person_uid, date_of_birth, gender, 
                                                 ethnicity_american_indian_or_alaska_native, ethnicity_asian,
                                                 ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
                                                 ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
                                                 ethnicity_other, 
 
row_number() over (partition by person_uid order by person_instance_id) as RowNbr 

from tr_ar_wdqi_2023.mdm_person_instance
) mpi

where RowNbr = 1

--To verify the count of records
select count(*) from
(select ssn_id  from ds_ar_dhe.graduated_student_table gst 
union
select ssn_id  from ds_ar_dhe.registration_table rt 
union
select ssn_id  from ds_ar_dhe.student_enrollment_table set2 
union
select ssn from ds_ar_dhs.snap_individual si 
union
select social_security_number from ds_ar_dhs.tanf_member tm 
union
select social_security_number from ds_ar_dws.jointpirl_raw_data jrd 
union
select social_security_number from ds_ar_dws.pirl p 
union
select ssn from ds_ar_dws.promis p2 
union
select employee_ssn from ds_ar_dws.ui_wages_lehd uwl 
union
select ssn from ds_ar_osd.rapids_apprentice ra)

MDM Person Traceability

insert Into tr_ar_wdqi_2023.mdm_person_traceability ( person_master_id, person_field_id, person_instance_id)
select mpm.person_master_id, '1' , mpi.person_instance_id  
from tr_ar_wdqi_2023.mdm_person_master mpm 
join tr_ar_wdqi_2023.mdm_person_instance mpi 
on mpm.person_uid = mpi.person_uid

Person Master - Updated

select * from (
select person_uid, date_of_birth, gender, 
         ethnicity_american_indian_or_alaska_native, ethnicity_asian,
         ethnicity_black_or_african_american, ethnicity_hispanic_or_latino,
         ethnicity_native_hawaiian_or_other_pacific_islander, ethnicity_white,
         ethnicity_other, (case when ((ethnicity_american_indian_or_alaska_native = 'Yes') or (ethnicity_american_indian_or_alaska_native = 'No')) then 1 else 0 end 
                                + case when ((ethnicity_asian = 'Yes') or (ethnicity_asian = 'No')) then 1 else 0 end 
                                + case when ((ethnicity_black_or_african_american = 'Yes') or (ethnicity_black_or_african_american = 'No')) then 1 else 0 end
                                + case when ((ethnicity_hispanic_or_latino = 'Yes') or (ethnicity_hispanic_or_latino = 'No')) then 1 else 0 end
                                + case when ((ethnicity_native_hawaiian_or_other_pacific_islander = 'Yes') or (ethnicity_native_hawaiian_or_other_pacific_islander = 'No')) then 1 else 0 end
                                + case when ((ethnicity_white = 'Yes') or (ethnicity_white = 'No')) then 1 else 0 end
                                + case when ((ethnicity_other = 'Yes') or (ethnicity_other = 'No')) then 1 else 0 end)
as CountOfNonNulls,
 
row_number() over (partition by person_uid order by CountOfNonNulls desc) as RowNbr 

from tr_e2e.mdm_person_instance
) mpi

where RowNbr = 1

person_mastering

create table if not exists tr_e2e.DIM_Person (
   Person_Key BIGINT not null,
   Person_UID CHAR(64) not null,
   Date_of_Birth DATE,
   Gender VARCHAR(10),
   Ethnicity_American_Indian_or_Alaska_Native VARCHAR(3),
   Ethnicity_Asian VARCHAR(3),
   Ethnicity_Black_or_African_American VARCHAR(3),
   Ethnicity_Hispanic_or_Latino VARCHAR(3),
   Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander VARCHAR(3),
   Ethnicity_White VARCHAR(3),
   Ethnicity_Other VARCHAR(3),
   constraint DIM_PERSON_PK_IDX primary key (Person_Key),
    unique (Person_UID)
);

GRANT UPDATE, SELECT, DELETE, REFERENCES ON TABLE tr_e2e.DIM_Person TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, REFERENCES ON TABLE tr_e2e.DIM_Person TO group db_t00113_rw;

-- Add "blank" person dimension record (ONLY RUN ONCE)
/*INSERT INTO tr_e2e.DIM_Person (Person_Key, Person_UID, Date_of_Birth, Gender, Ethnicity_American_Indian_or_Alaska_Native,
                              Ethnicity_Asian, Ethnicity_Black_or_African_American, Ethnicity_Hispanic_or_Latino,
                              Ethnicity_Native_Hawaiian_or_Other_Pacific_Islander, Ethnicity_White, Ethnicity_Other)
VALUES (REDACTED, '', CAST('9999-01-01' AS DATE), REDACTED, REDACTED, REDACTED, REDACTED, REDACTED, REDACTED, REDACTED, REDACTED); */

insert into tr_e2e.dim_person( 
    person_key,
    person_uid, 
    gender, 
    date_of_birth, 
    ethnicity_american_indian_or_alaska_native,
    ethnicity_asian,
    ethnicity_black_or_african_american,
    ethnicity_hispanic_or_latino,
    ethnicity_native_hawaiian_or_other_pacific_islander,
    ethnicity_white,
    ethnicity_other
)
with gender_tab as (
    select person_uid, gender, count(*) as cnt, row_number() over (partition by person_uid order by count(*) desc,
        --breaking ties when highest count is same for multiple gender values 
        --in future, would prefer to break tie by recency of observation, but not tracked in person_instance 
        case when gender = 'Other' then 1
        when gender = 'Female' then 2
        when gender = 'Male' then 3
        else 4 end
    ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where gender not in ('', 'Unknown', 'Missing')
    group by person_uid, gender
),
gender_tab2 as (
    select * 
    from gender_tab 
    where rn = 1
),
dob_tab as (
    select person_uid, date_of_birth, count(*) as cnt, 
        --in ties of number of observations, order by date of birth 
        row_number() over (partition by person_uid order by count(*) desc, date_of_birth) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where date_of_birth != '1900-01-01'
    group by person_uid, date_of_birth 
),
dob_tab2 as ( 
    select * 
    from dob_tab 
    where rn = 1
),
eth_aian_tab as (
    select person_uid, ethnicity_american_indian_or_alaska_native, count(*) as cnt, 
        --in ties of number of observations, prioritize yes over no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_american_indian_or_alaska_native = 'Yes' then 1 
            when ethnicity_american_indian_or_alaska_native = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_american_indian_or_alaska_native not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_american_indian_or_alaska_native 
),
eth_aian_tab2 as ( 
    select * 
    from eth_aian_tab 
    where rn = 1
),
eth_asian_tab as (
    select person_uid, ethnicity_asian, count(*) as cnt, 
        --in ties of number of observations, prioritize yes over no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_asian = 'Yes' then 1 
            when ethnicity_asian = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_asian not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_asian  
),
eth_asian_tab2 as ( 
    select *
    from eth_asian_tab 
    where rn = 1
),
eth_baa_tab as (
    select person_uid, ethnicity_black_or_african_american, count(*) as cnt, 
        --in ties of number of observations, prioritize yes over no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_black_or_african_american = 'Yes' then 1 
            when ethnicity_black_or_african_american = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_asian not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_black_or_african_american  
),
eth_baa_tab2 as ( 
    select * 
    from eth_baa_tab 
    where rn = 1
),
eth_hl_tab as (
    select person_uid, ethnicity_hispanic_or_latino, count(*) as cnt, 
        --in ties of number of observations, prioritize yes or no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_hispanic_or_latino = 'Yes' then 1 
            when ethnicity_hispanic_or_latino = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_hispanic_or_latino not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_hispanic_or_latino 
),
eth_hl_tab2 as ( 
    select *
    from eth_hl_tab 
    where rn = 1
),
eth_nhpi_tab as (
    select person_uid, ethnicity_native_hawaiian_or_other_pacific_islander, count(*) as cnt, 
        --in ties of number of observations, prioritize yes or no
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_native_hawaiian_or_other_pacific_islander = 'Yes' then 1 
            when ethnicity_native_hawaiian_or_other_pacific_islander = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_native_hawaiian_or_other_pacific_islander not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_native_hawaiian_or_other_pacific_islander 
),
eth_nhpi_tab2 as ( 
    select *
    from eth_nhpi_tab 
    where rn = 1
),
eth_white_tab as (
    select person_uid, ethnicity_white, count(*) as cnt, 
        --in ties of number of observations, prioritize yes or no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_white = 'Yes' then 1 
            when ethnicity_white = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_white not in ('', 'MI', 'UK')
    group by person_uid, ethnicity_white  
),
eth_white_tab2 as (
    select * 
    from eth_white_tab 
    where rn = 1
),
eth_other_tab as ( 
    select person_uid, ethnicity_other, count(*) as cnt, 
        --in ties of number of observations, prioritize yes or no 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_other = '2+' then 1 
            when ethnicity_other = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_other not in ('', 'NC', 'N/A')
    group by person_uid, ethnicity_other
),
eth_other_tab2 as (
    select *
    from eth_other_tab 
    where rn = 1
),
unique_ppl as (
    select distinct person_uid 
    from tr_e2e.mdm_person_instance mpi2 
), 
gd as (
    select coalesce(gt.person_uid, dt.person_uid) as person_uid, 
        gt.gender,
        dt.date_of_birth
    from gender_tab2 gt 
    full outer join dob_tab2 dt on (gt.person_uid = dt.person_uid)
),
gda as (
    select coalesce(eat.person_uid, gd.person_uid) as person_uid, 
    gd.gender, 
    gd.date_of_birth, 
    eat.ethnicity_american_indian_or_alaska_native 
    from eth_aian_tab2 eat
    full outer join gd on gd.person_uid = eat.person_uid
),
gdaa as (
    select coalesce(east.person_uid, gda.person_uid) as person_uid, 
    gda.gender, 
    gda.date_of_birth, 
    gda.ethnicity_american_indian_or_alaska_native,
    east.ethnicity_asian
    from eth_asian_tab2 east
    full outer join gda on gda.person_uid = east.person_uid
),
gdaab as (
    select coalesce(ebt.person_uid, gdaa.person_uid) as person_uid, 
    gdaa.gender, 
    gdaa.date_of_birth, 
    gdaa.ethnicity_american_indian_or_alaska_native,
    gdaa.ethnicity_asian,
    ebt.ethnicity_black_or_african_american
    from gdaa 
    full outer join eth_baa_tab2 ebt on (gdaa.person_uid = ebt.person_uid)
),
gdaabh as (
    select coalesce(eht.person_uid, gdaab.person_uid) as person_uid, 
    gdaab.gender, 
    gdaab.date_of_birth, 
    gdaab.ethnicity_american_indian_or_alaska_native,
    gdaab.ethnicity_asian,
    gdaab.ethnicity_black_or_african_american,
    eht.ethnicity_hispanic_or_latino
    from gdaab
    full outer join eth_hl_tab2 eht on (gdaab.person_uid = eht.person_uid)
),
gdaabhn as (
    select coalesce(ent.person_uid, gdaabh.person_uid) as person_uid, 
    gdaabh.gender, 
    gdaabh.date_of_birth, 
    gdaabh.ethnicity_american_indian_or_alaska_native,
    gdaabh.ethnicity_asian,
    gdaabh.ethnicity_black_or_african_american,
    gdaabh.ethnicity_hispanic_or_latino,
    ent.ethnicity_native_hawaiian_or_other_pacific_islander
    from gdaabh
    full outer join eth_nhpi_tab2 ent on (gdaabh.person_uid = ent.person_uid)
),
gdaabhnw as ( 
    select coalesce(ewt.person_uid, gdaabhn.person_uid) as person_uid, 
    gdaabhn.gender, 
    gdaabhn.date_of_birth, 
    gdaabhn.ethnicity_american_indian_or_alaska_native,
    gdaabhn.ethnicity_asian,
    gdaabhn.ethnicity_black_or_african_american,
    gdaabhn.ethnicity_hispanic_or_latino,
    gdaabhn.ethnicity_native_hawaiian_or_other_pacific_islander,
    ewt.ethnicity_white
    from gdaabhn
    full outer join eth_white_tab2 ewt on (gdaabhn.person_uid = ewt.person_uid)
),
gdaabhnwo as ( 
    select coalesce(eot.person_uid, gdaabhnw.person_uid) as person_uid, 
    gdaabhnw.gender, 
    gdaabhnw.date_of_birth, 
    gdaabhnw.ethnicity_american_indian_or_alaska_native,
    gdaabhnw.ethnicity_asian,
    gdaabhnw.ethnicity_black_or_african_american,
    gdaabhnw.ethnicity_hispanic_or_latino,
    gdaabhnw.ethnicity_native_hawaiian_or_other_pacific_islander,
    gdaabhnw.ethnicity_white,
    eot.ethnicity_other
    from gdaabhnw
    full outer join eth_other_tab2 eot on (gdaabhnw.person_uid = eot.person_uid)
),
all_comb as (
    select coalesce(up.person_uid, gdaabhnwo.person_uid) as person_uid, 
    gdaabhnwo.gender, 
    gdaabhnwo.date_of_birth, 
    gdaabhnwo.ethnicity_american_indian_or_alaska_native,
    gdaabhnwo.ethnicity_asian,
    gdaabhnwo.ethnicity_black_or_african_american,
    gdaabhnwo.ethnicity_hispanic_or_latino,
    gdaabhnwo.ethnicity_native_hawaiian_or_other_pacific_islander,
    gdaabhnwo.ethnicity_white,
    gdaabhnwo.ethnicity_other
    from gdaabhnwo
    full outer join unique_ppl up on (gdaabhnwo.person_uid = up.person_uid)
),
get_key as (
select mpm.person_master_id as person_key, all_comb.* 
from all_comb 
inner join tr_e2e.mdm_person_master mpm on mpm.person_uid = all_comb.person_uid
)
select * from get_key 



--testing protocol - develop logic and test for someone with multiple non-missing values to make sure it works
--example below 

with f as (
    select person_uid, ethnicity_other, count(*) as cnt, 
        --in ties of number of observations, order by INSERT VARIABLE 
        row_number() over (partition by person_uid order by count(*) desc, 
            case when ethnicity_other = '2+' then 1 
            when ethnicity_other = 'No' then 2 
            else 3 end
        ) as rn 
    from tr_e2e.mdm_person_instance mpi 
    where ethnicity_other not in ('', 'NC', 'N/A')
    group by person_uid, ethnicity_other
),
dup as (
    select person_uid from tr_e2e.mdm_person_instance mpi where ethnicity_other not in ('', 'NC', 'N/A')
    group by person_uid having count(distinct(ethnicity_other)) > 1
    limit 1
)
select * from f where person_uid in (select distinct person_uid from dup)

Coleridge Initiative Adjustments

new_fact_populate

select distinct person_key, program_key, entry_year_quarter_key, max(exit_year_quarter_key) as exit_year_quarter_key
from tr_e2e.fact_person_program_participation fppp 
where program_key != 11
group by person_key, program_key, entry_year_quarter_key
order by person_key, program_key, entry_year_quarter_key 

new_fact_table_creation

create table if not exists tr_e2e.FACT_Person_Program_Start_End (
   Person_Program_Start_End_ID BIGINT not null identity,
   Person_Key BIGINT not null,
   Program_Key INTEGER not null,
   Entry_Year_Quarter_Key INTEGER not null,
   Exit_Year_Quarter_Key INTEGER not null,
   constraint PK_FACT_Person_Program_Start_End_IDX primary key (Person_Program_Start_End_ID),
    unique (Person_Key, Program_Key, Entry_Year_Quarter_Key, Exit_Year_Quarter_Key),
   constraint FK_FACT_PERSON_Program_Start_End_DIM_PROGRAM foreign key (Program_Key) 
      references tr_e2e.DIM_Program (Program_Key),
   constraint FK_FACT_PERSON_Program_Start_End_DIM_YEAR_QUARTER_Entry foreign key (Entry_Year_Quarter_Key) 
      references tr_e2e.DIM_Year_Quarter (Year_Quarter_Key),
   constraint FK_FACT_PERSON_Program_Start_End_DIM_PERSON foreign key (Person_Key) 
      references tr_e2e.DIM_Person (Person_Key),
   constraint FK_FACT_PERSON_Program_Start_End_DIM_YEAR_QUARTER__EXIT_YEAR foreign key (Exit_Year_Quarter_Key) 
      references tr_e2e.DIM_Year_Quarter (Year_Quarter_Key)
);

insert into tr_e2e.fact_person_program_start_end( 
    person_key,
    program_key,
    entry_year_quarter_key,
    exit_year_quarter_key 
)
select distinct person_key, program_key, entry_year_quarter_key, max(exit_year_quarter_key) as exit_year_quarter_key
from tr_e2e.fact_person_program_participation fppp 
where program_key != 11
group by person_key, program_key, entry_year_quarter_key
order by person_key, program_key, entry_year_quarter_key 

GRANT UPDATE, SELECT, DELETE, REFERENCES ON TABLE tr_e2e.FACT_Person_Program_Start_End TO group ci_read_group;
GRANT UPDATE, SELECT, DELETE, REFERENCES ON TABLE tr_e2e.FACT_Person_Program_Start_End TO group db_t00113_rw;

update_fks

alter table tr_e2e.fact_person_ui_wage 
add constraint FK_FACT_PERSON_UI_WAGE__DIM_PERSON foreign key (Person_Key) 
      references tr_e2e.DIM_Person (Person_Key)