├── 00 Totally Optional HMIS Table Indexes.sql ├── 01 Temp Reporting and Reference Tables.sql ├── 02 LSA Output Tables.sql ├── 03_01a LSA Parameters and Metadata.sql ├── 03_01b LSA Parameters and Metadata for HIC.sql ├── 03_02 to 03_06 HMIS Households and Enrollments.sql ├── 04_01 Get Project Records.sql ├── 04_02 to 04_08 Get Other PDDEs.sql ├── 05_01 to 05_11 LSAPerson Records and Demographics.sql ├── 05_12 to 05_15 LSAPerson Project Group and Population Household Types.sql ├── 06 LSAHousehold.sql ├── 07 LSAExit.sql ├── 08 LSACalculated Averages for LSAHousehold and LSAExit.sql ├── 09 LSACalculated AHAR Counts.sql ├── 10 LSACalculated Data Quality.sql ├── 11 LSAReport DQ and ReportDate.sql ├── Full Flag List for Vendors.xlsx ├── LSA Data Dictionary FY2024.xlsx ├── LSA Programming Specifications FY2024 - Annotated.docx ├── LSA Programming Specifications FY2024.docx ├── README.md └── Sample Data ├── Sample Data.zip ├── Sample HIC Output.zip ├── Sample HIC Temp Tables.zip ├── Sample HMIS Data.zip ├── Sample LSA Output.zip └── Sample LSA Temp Tables.zip /00 Totally Optional HMIS Table Indexes.sql: -------------------------------------------------------------------------------- 1 | /* 2 | 3 | LSA FY2024 Sample Code 4 | Name: 00 Totally Optional HMIS Table Indexes.sql 5 | 6 | */ 7 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_TimesHomelessPastThreeYears_MonthsHomelessPastThreeYears') 8 | begin 9 | create nonclustered index ix_hmis_Enrollment_TimesHomelessPastThreeYears_MonthsHomelessPastThreeYears on hmis_Enrollment (TimesHomelessPastThreeYears, MonthsHomelessPastThreeYears) include (EnrollmentID) 10 | end 11 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_DateDeleted_EntryDate') 12 | begin 13 | create nonclustered index ix_hmis_Enrollment_DateDeleted_EntryDate on hmis_Enrollment (DateDeleted, EntryDate) include (EnrollmentID, HouseholdID, ProjectID, RelationshipToHoH) 14 | end 15 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_HouseholdID_DateDeleted_EntryDate_RelationshipToHoH') 16 | begin 17 | create nonclustered index ix_hmis_Enrollment_HouseholdID_DateDeleted_EntryDate_RelationshipToHoH on hmis_Enrollment (HouseholdID, DateDeleted, EntryDate, RelationshipToHoH) include (EnrollmentID, PersonalID, DisablingCondition) 18 | end 19 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_EntryDate') 20 | begin 21 | create nonclustered index ix_hmis_Enrollment_EntryDate on hmis_Enrollment (EntryDate) include (EnrollmentID, ProjectID, HouseholdID, RelationshipToHoH, DateDeleted) 22 | end 23 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_HouseholdID_DateDeleted_RelationshipToHoH') 24 | begin 25 | create nonclustered index ix_hmis_Enrollment_HouseholdID_DateDeleted_RelationshipToHoH on hmis_Enrollment (HouseholdID, DateDeleted, RelationshipToHoH) include (EnrollmentID, PersonalID, EntryDate, DisablingCondition) 26 | end 27 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_MoveInDate') 28 | begin 29 | create nonclustered index ix_hmis_Enrollment_MoveInDate on hmis_Enrollment (MoveInDate) include (EnrollmentID) 30 | end 31 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_LivingSituation') 32 | begin 33 | create nonclustered index ix_hmis_Enrollment_LivingSituation on hmis_Enrollment (LivingSituation) include (EnrollmentID) 34 | end 35 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_LengthOfStay') 36 | begin 37 | create nonclustered index ix_hmis_Enrollment_LengthOfStay on hmis_Enrollment (LengthOfStay) include (EnrollmentID) 38 | end 39 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_HouseholdID_RelationshipToHoH_DateDeleted') 40 | begin 41 | create nonclustered index ix_hmis_Enrollment_HouseholdID_RelationshipToHoH_DateDeleted on hmis_Enrollment (HouseholdID, RelationshipToHoH, DateDeleted) include (EnrollmentID) 42 | end 43 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_ProjectID_RelationshipToHoH_DateDeleted') 44 | begin 45 | create nonclustered index ix_hmis_Enrollment_ProjectID_RelationshipToHoH_DateDeleted on hmis_Enrollment (ProjectID, RelationshipToHoH, DateDeleted) include (EnrollmentID, PersonalID, EntryDate, HouseholdID, MoveInDate) 46 | end 47 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_RelationshipToHoH_DateDeleted') 48 | begin 49 | create nonclustered index ix_hmis_Enrollment_RelationshipToHoH_DateDeleted on hmis_Enrollment (RelationshipToHoH, DateDeleted) include (EnrollmentID, PersonalID, ProjectID, EntryDate, HouseholdID, MoveInDate) 50 | end 51 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_MonthsHomelessPastThreeYears') 52 | begin 53 | create nonclustered index ix_hmis_Enrollment_MonthsHomelessPastThreeYears on hmis_Enrollment (MonthsHomelessPastThreeYears) include (EnrollmentID, LivingSituation, PreviousStreetESSH) 54 | end 55 | if not exists (select * from sys.indexes where name = 'ix_hmis_Exit_DateDeleted') 56 | begin 57 | create nonclustered index ix_hmis_Exit_DateDeleted on hmis_Exit (DateDeleted) include (EnrollmentID, ExitDate) 58 | end 59 | if not exists (select * from sys.indexes where name = 'ix_hmis_Exit_ExitDate_Destination') 60 | begin 61 | create nonclustered index ix_hmis_Exit_ExitDate_Destination on hmis_Exit (ExitDate, Destination) include (EnrollmentID) 62 | end 63 | if not exists (select * from sys.indexes where name = 'ix_hmis_Services_EnrollmentID_RecordType_DateDeleted') 64 | begin 65 | create nonclustered index ix_hmis_Services_EnrollmentID_RecordType_DateDeleted on hmis_Services (EnrollmentID, RecordType, DateDeleted) include (DateProvided) 66 | end 67 | if not exists (select * from sys.indexes where name = 'ix_hmis_Services_RecordType_DateDeleted_DateProvided') 68 | begin 69 | create nonclustered index ix_hmis_Services_RecordType_DateDeleted_DateProvided on hmis_Services (RecordType, DateDeleted, DateProvided) include (EnrollmentID) 70 | end 71 | if not exists (select * from sys.indexes where name = 'ix_hmis_Disabilities_DisabilityType_DisabilityResponse_IndefiniteAndImpairs_InformationDate') 72 | begin 73 | create nonclustered index ix_hmis_Disabilities_DisabilityType_DisabilityResponse_IndefiniteAndImpairs_InformationDate on hmis_Disabilities (DisabilityType, DisabilityResponse, IndefiniteAndImpairs,InformationDate) include (EnrollmentID) 74 | end 75 | if not exists (select * from sys.indexes where name = 'ix_hmis_Disabilities_DisabilityType_DisabilityResponse_IndefiniteAndImpairs') 76 | begin 77 | create nonclustered index ix_hmis_Disabilities_DisabilityType_DisabilityResponse_IndefiniteAndImpairs on hmis_Disabilities (DisabilityType, DisabilityResponse, IndefiniteAndImpairs) INCLUDE (EnrollmentID, InformationDate) 78 | end 79 | if not exists (select * from sys.indexes where name = 'ix_hmis_Enrollment_ProjectID_RelationshipToHoH_DateDeleted_EntryDate') 80 | begin 81 | create nonclustered index ix_hmis_Enrollment_ProjectID_RelationshipToHoH_DateDeleted_EntryDate on hmis_Enrollment (ProjectID, RelationshipToHoH, DateDeleted,EntryDate) include (HouseholdID, EnrollmentCoC) 82 | end 83 | 84 | if not exists (select * from sys.indexes where name = 'ix_hmis_HealthAndDV_InformationDate_DateDeleted') 85 | begin 86 | create nonclustered index ix_hmis_HealthAndDV_InformationDate_DateDeleted on hmis_HealthAndDV (InformationDate, DateDeleted) include ([EnrollmentID], [DomesticViolenceSurvivor], [CurrentlyFleeing]) 87 | end 88 | -------------------------------------------------------------------------------- /02 LSA Output Tables.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 02 LSA Output Tables.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | 12 | It is not necessary to execute this code every time the LSA is run -- only 13 | if/when there are changes to it. It creates tables in the structure of the 14 | LSA CSV files. 15 | 16 | There are some deliberate differences from data typing and nullability as defined by 17 | the HMIS CSV/LSA specs and the CREATE statements here. 18 | 19 | Columns which may be NULL in the HMIS CSV under some circumstances that do not 20 | apply to the LSA upload are created as NOT NULL here. For example, ProjectType 21 | may be NULL in HMIS if ContinuumProject = 0, but may not be NULL in the LSA 22 | because all projects included in the upload must have ContinuumProject = 1. 23 | 24 | Columns which may not be NULL in HMIS but are not relevant to the LSA are 25 | created as NULL here. For example, UserID values are not imported to the HDX 26 | and may be NULL in the LSA upload. 27 | 28 | Date columns are created with data type nvarchar to enable date formatting as 29 | required by HMIS/LSA CSV specs in the INSERT statements. The only exception is 30 | DateDeleted columns -- they must be NULL for all records and formatting is not 31 | relevant. 32 | 33 | ExportID columns have a string(32) data type for HMIS purposes, but the values 34 | must match the LSA ReportID, which is an int column; they are created here as int 35 | to ensure that the data type, at least, is consistent with LSA requirements. 36 | 37 | 38 | 2.1 Project.csv / lsa_Project 39 | */ 40 | if object_id ('lsa_Project') is not NULL drop table lsa_Project 41 | 42 | -- ProjectType and HousingType may be NULL under some circumstances in the HMIS CSV; 43 | -- none of those circumstances apply to projects included in the LSA upload. 44 | 45 | create table lsa_Project( 46 | ProjectID nvarchar(32) not NULL, 47 | OrganizationID nvarchar(32) not NULL, 48 | ProjectName nvarchar(200) not NULL, 49 | ProjectCommonName nvarchar(200), 50 | OperatingStartDate nvarchar(10) not NULL, --HMIS: date 51 | OperatingEndDate nvarchar(10), --HMIS: date 52 | ContinuumProject int not NULL, 53 | ProjectType int not NULL, --HMIS: may be NULL 54 | HousingType int, 55 | RRHSubType int, 56 | ResidentialAffiliation int, 57 | TargetPopulation int, 58 | HOPWAMedAssistedLivingFac int, 59 | PITCount int, 60 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 61 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 62 | UserID nvarchar(32), --HMIS: not NULL 63 | DateDeleted datetime, 64 | ExportID int not NULL, --HMIS: string(32) 65 | CONSTRAINT pk_lsa_Project PRIMARY KEY CLUSTERED (ProjectID) 66 | ) 67 | 68 | /* 69 | 2.2 Organization.csv / lsa_Organization 70 | */ 71 | if object_id ('lsa_Organization') is not NULL drop table lsa_Organization 72 | 73 | create table lsa_Organization( 74 | OrganizationID nvarchar(32) not NULL, 75 | OrganizationName nvarchar(200) not NULL, 76 | VictimServiceProvider int not NULL, 77 | OrganizationCommonName nvarchar(200), 78 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 79 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 80 | UserID nvarchar(32), --HMIS: not NULL 81 | DateDeleted datetime, 82 | ExportID int not NULL, --HMIS: string(32) 83 | CONSTRAINT pk_lsa_Organization PRIMARY KEY CLUSTERED (OrganizationID) 84 | ) 85 | 86 | /* 87 | 2.3 Funder.csv / lsa_Funder 88 | */ 89 | 90 | if object_id ('lsa_Funder') is not NULL drop table lsa_Funder 91 | 92 | -- GrantID may not be NULL in HMIS, but it is not relevant for the LSA. 93 | 94 | create table lsa_Funder( 95 | FunderID nvarchar(32) not NULL, 96 | ProjectID nvarchar(32) not NULL, 97 | Funder int not NULL, 98 | OtherFunder nvarchar(100), 99 | GrantID nvarchar(100), --HMIS: not NULL 100 | StartDate nvarchar(10) not NULL, --HMIS: date 101 | EndDate nvarchar(10), --HMIS: date 102 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 103 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 104 | UserID nvarchar(32), --HMIS: not NULL 105 | DateDeleted datetime, 106 | ExportID int not NULL, --HMIS: string(32) 107 | CONSTRAINT pk_lsa_Funder PRIMARY KEY CLUSTERED (FunderID) 108 | ) 109 | 110 | /* 111 | 2.4 ProjectCoC.csv / lsa_ProjectCoC 112 | */ 113 | if object_id ('lsa_ProjectCoC') is not NULL drop table lsa_ProjectCoC 114 | 115 | -- ZIP and GeographyType are mandatory for the LSA. 116 | create table lsa_ProjectCoC( 117 | ProjectCoCID nvarchar(32) not NULL, 118 | ProjectID nvarchar(32) not NULL, 119 | CoCCode nvarchar(6) not NULL, 120 | Geocode nvarchar(6) not NULL, 121 | Address1 nvarchar(100), 122 | Address2 nvarchar(100), 123 | City nvarchar(50), 124 | [State] nvarchar(2), 125 | ZIP nvarchar(5), 126 | GeographyType int, 127 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 128 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 129 | UserID nvarchar(32), --HMIS: not NULL 130 | DateDeleted datetime, 131 | ExportID int not NULL, --HMIS: string(32) 132 | CONSTRAINT pk_lsa_ProjectCoC PRIMARY KEY CLUSTERED (ProjectCoCID) 133 | ) 134 | 135 | /* 136 | 2.5 Inventory.csv / lsa_Inventory 137 | */ 138 | if object_id ('lsa_Inventory') is not NULL drop table lsa_Inventory 139 | 140 | -- xInventory (e.g., CHVetBedInventory, etc.) columns for which the HMIS CSV permits 141 | -- NULL values are mandatory for the LSA and created here as NOT NULL. 142 | -- BedInventory MUST be equal to the sum of values in xInventory columns. It is set up 143 | -- here as a computed column, which is permissible. 144 | create table lsa_Inventory( 145 | InventoryID nvarchar(32) not NULL, 146 | ProjectID nvarchar(32) not NULL, 147 | CoCCode nvarchar(6) not NULL, 148 | HouseholdType int not NULL, 149 | [Availability] int, 150 | UnitInventory int not NULL, 151 | BedInventory 152 | as CHVetBedInventory + YouthVetBedInventory + VetBedInventory 153 | + CHYouthBedInventory + YouthBedInventory + CHBedInventory 154 | + OtherBedInventory, 155 | CHVetBedInventory int not NULL, --HMIS: may be NULL 156 | YouthVetBedInventory int not NULL, --HMIS: may be NULL 157 | VetBedInventory int not NULL, --HMIS: may be NULL 158 | CHYouthBedInventory int not NULL, --HMIS: may be NULL 159 | YouthBedInventory int not NULL, --HMIS: may be NULL 160 | CHBedInventory int not NULL, --HMIS: may be NULL 161 | OtherBedInventory int not NULL, --HMIS: may be NULL 162 | ESBedType int, 163 | InventoryStartDate nvarchar(10) not NULL, --HMIS: date 164 | InventoryEndDate nvarchar(10), --HMIS: date 165 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 166 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 167 | UserID nvarchar(32), --HMIS: not NULL 168 | DateDeleted datetime, 169 | ExportID int not NULL, --HMIS: string(32) 170 | CONSTRAINT pk_lsa_Inventory PRIMARY KEY CLUSTERED (InventoryID) 171 | ) 172 | 173 | /* 174 | 2.6 HMISParticipation.csv / lsa_HMISParticipation 175 | */ 176 | if object_id ('lsa_HMISParticipation') is not NULL drop table lsa_HMISParticipation 177 | 178 | create table lsa_HMISParticipation ( 179 | HMISParticipationID nvarchar(32) not NULL, 180 | ProjectID nvarchar(32) not NULL, 181 | HMISParticipationType int not NULL, 182 | HMISParticipationStatusStartDate nvarchar(10) not NULL, --HMIS: date 183 | HMISParticipationStatusEndDate nvarchar(10), --HMIS: date 184 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 185 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 186 | UserID nvarchar(32), --HMIS: not NULL 187 | DateDeleted datetime, 188 | ExportID int not NULL, --HMIS: string(32) 189 | CONSTRAINT pk_lsa_HMISParticipation PRIMARY KEY CLUSTERED (HMISParticipationID) 190 | ) 191 | 192 | /* 193 | 2.7 Affiliation.csv / lsa_Affiliation 194 | */ 195 | if object_id ('lsa_Affiliation') is not NULL drop table lsa_Affiliation 196 | 197 | create table lsa_Affiliation ( 198 | AffiliationID nvarchar(32) not NULL, 199 | ProjectID nvarchar(32) not NULL, 200 | ResProjectID nvarchar(32) not NULL, 201 | DateCreated nvarchar(19) not NULL, --HMIS: datetime 202 | DateUpdated nvarchar(19) not NULL, --HMIS: datetime 203 | UserID nvarchar(32), --HMIS: not NULL 204 | DateDeleted datetime, 205 | ExportID int not NULL, --HMIS: string(32) 206 | CONSTRAINT pk_lsa_Affiliation PRIMARY KEY CLUSTERED (AffiliationID) 207 | ) 208 | 209 | /* 210 | 2.8 LSAReport.csv / lsa_Report 211 | */ 212 | if object_id ('lsa_Report') is not NULL drop table lsa_Report 213 | 214 | -- The NULL/NOT NULL requirements for this table as it is created here 215 | -- differ from those for the LSAReport.csv file because the values are not 216 | -- populated in a single step. All columns must be non-NULL in the upload. 217 | create table lsa_Report( 218 | ReportID int not NULL, 219 | ReportDate datetime, 220 | ReportStart date not NULL, 221 | ReportEnd date not NULL, 222 | ReportCoC nvarchar(6) not NULL, 223 | SoftwareVendor nvarchar(50) not NULL, 224 | SoftwareName nvarchar(50) not NULL, 225 | VendorContact nvarchar(50) not NULL, 226 | VendorEmail nvarchar(50) not NULL, 227 | LSAScope int not NULL, 228 | LookbackDate date not NULL, 229 | NoCoC int, 230 | NotOneHoH int, 231 | RelationshipToHoH int, 232 | MoveInDate int, 233 | UnduplicatedClient int, 234 | HouseholdEntry int, 235 | ClientEntry int, 236 | AdultHoHEntry int, 237 | ClientExit int, 238 | SSNNotProvided int, 239 | SSNMissingOrInvalid int, 240 | ClientSSNNotUnique int, 241 | DistinctSSNValueNotUnique int, 242 | DisablingCond int, 243 | LivingSituation int, 244 | LengthOfStay int, 245 | HomelessDate int, 246 | TimesHomeless int, 247 | MonthsHomeless int, 248 | Destination int 249 | ) 250 | 251 | /* 252 | 2.9 LSAPerson.csv / lsa_Person 253 | */ 254 | 255 | if object_id ('lsa_Person') is not NULL drop table lsa_Person 256 | 257 | create table lsa_Person ( 258 | RowTotal int not NULL, 259 | Gender int not NULL, 260 | RaceEthnicity int not NULL, 261 | VetStatus int not NULL, 262 | DisabilityStatus int not NULL, 263 | CHTime int not NULL, 264 | CHTimeStatus int not NULL, 265 | DVStatus int not NULL, 266 | ESTAgeMin int not NULL, 267 | ESTAgeMax int not NULL, 268 | HHTypeEST int not NULL, 269 | HoHEST int not NULL, 270 | AdultEST int not NULL, 271 | AHARAdultEST int not NULL, 272 | HHChronicEST int not NULL, 273 | HHVetEST int not NULL, 274 | HHDisabilityEST int not NULL, 275 | HHFleeingDVEST int not NULL, 276 | HHAdultAgeAOEST int not NULL, 277 | HHAdultAgeACEST int not NULL, 278 | HHParentEST int not NULL, 279 | AC3PlusEST int not NULL, 280 | AHAREST int not NULL, 281 | AHARHoHEST int not NULL, 282 | RRHAgeMin int not NULL, 283 | RRHAgeMax int not NULL, 284 | HHTypeRRH int not NULL, 285 | HoHRRH int not NULL, 286 | AdultRRH int not NULL, 287 | AHARAdultRRH int not NULL, 288 | HHChronicRRH int not NULL, 289 | HHVetRRH int not NULL, 290 | HHDisabilityRRH int not NULL, 291 | HHFleeingDVRRH int not NULL, 292 | HHAdultAgeAORRH int not NULL, 293 | HHAdultAgeACRRH int not NULL, 294 | HHParentRRH int not NULL, 295 | AC3PlusRRH int not NULL, 296 | AHARRRH int not NULL, 297 | AHARHoHRRH int not NULL, 298 | PSHAgeMin int not NULL, 299 | PSHAgeMax int not NULL, 300 | HHTypePSH int not NULL, 301 | HoHPSH int not NULL, 302 | AdultPSH int not NULL, 303 | AHARAdultPSH int not NULL, 304 | HHChronicPSH int not NULL, 305 | HHVetPSH int not NULL, 306 | HHDisabilityPSH int not NULL, 307 | HHFleeingDVPSH int not NULL, 308 | HHAdultAgeAOPSH int not NULL, 309 | HHAdultAgeACPSH int not NULL, 310 | HHParentPSH int not NULL, 311 | AC3PlusPSH int not NULL, 312 | AHARPSH int not NULL, 313 | AHARHoHPSH int not NULL, 314 | RRHSOAgeMin int not NULL, 315 | RRHSOAgeMax int not NULL, 316 | HHTypeRRHSONoMI int not NULL, 317 | HHTypeRRHSOMI int not NULL, 318 | HHTypeES int not null, 319 | HHTypeSH int not null, 320 | HHTypeTH int not null, 321 | HIV int not NULL, 322 | SMI int not NULL, 323 | SUD int not NULL, 324 | ReportID int not NULL 325 | ) 326 | 327 | /* 328 | 2.10 LSAHousehold.csv / lsa_Household 329 | */ 330 | if object_id ('lsa_Household') is not NULL drop table lsa_Household 331 | 332 | create table lsa_Household( 333 | RowTotal int not NULL, 334 | Stat int not NULL, 335 | ReturnTime int not NULL, 336 | HHType int not NULL, 337 | HHChronic int not NULL, 338 | HHVet int not NULL, 339 | HHDisability int not NULL, 340 | HHFleeingDV int not NULL, 341 | HoHRaceEthnicity int not NULL, 342 | HHAdult int not NULL, 343 | HHChild int not NULL, 344 | HHNoDOB int not NULL, 345 | HHAdultAge int not NULL, 346 | HHParent int not NULL, 347 | ESTStatus int not NULL, 348 | ESTGeography int not NULL, 349 | ESTLivingSit int not NULL, 350 | ESTDestination int not NULL, 351 | ESTChronic int not NULL, 352 | ESTVet int not NULL, 353 | ESTDisability int not NULL, 354 | ESTFleeingDV int not NULL, 355 | ESTAC3Plus int not NULL, 356 | ESTAdultAge int not NULL, 357 | ESTParent int not NULL, 358 | RRHStatus int not NULL, 359 | RRHMoveIn int not NULL, 360 | RRHGeography int not NULL, 361 | RRHLivingSit int not NULL, 362 | RRHDestination int not NULL, 363 | RRHPreMoveInDays int not NULL, 364 | RRHChronic int not NULL, 365 | RRHVet int not NULL, 366 | RRHDisability int not NULL, 367 | RRHFleeingDV int not NULL, 368 | RRHAC3Plus int not NULL, 369 | RRHAdultAge int not NULL, 370 | RRHParent int not NULL, 371 | PSHStatus int not NULL, 372 | PSHMoveIn int not NULL, 373 | PSHGeography int not NULL, 374 | PSHLivingSit int not NULL, 375 | PSHDestination int not NULL, 376 | PSHHousedDays int not NULL, 377 | PSHChronic int not NULL, 378 | PSHVet int not NULL, 379 | PSHDisability int not NULL, 380 | PSHFleeingDV int not NULL, 381 | PSHAC3Plus int not NULL, 382 | PSHAdultAge int not NULL, 383 | PSHParent int not NULL, 384 | ESDays int not NULL, 385 | THDays int not NULL, 386 | ESTDays int not NULL, 387 | RRHPSHPreMoveInDays int not NULL, 388 | RRHHousedDays int not NULL, 389 | SystemDaysNotPSHHoused int not NULL, 390 | SystemHomelessDays int not NULL, 391 | Other3917Days int not NULL, 392 | TotalHomelessDays int not NULL, 393 | SystemPath int not NULL, 394 | ESTAHAR int not NULL, 395 | RRHAHAR int not NULL, 396 | PSHAHAR int not NULL, 397 | RRHSOStatus int not NULL, 398 | RRHSOMoveIn int not NULL, 399 | ReportID int not NULL 400 | ) 401 | 402 | /* 403 | 2.11 LSAExit.csv / lsa_Exit 404 | */ 405 | if object_id ('lsa_Exit') is not NULL drop table lsa_Exit 406 | 407 | create table lsa_Exit( 408 | RowTotal int not NULL, 409 | Cohort int not NULL, 410 | Stat int not NULL, 411 | ExitFrom int not NULL, 412 | ExitTo int not NULL, 413 | ReturnTime int not NULL, 414 | HHType int not NULL, 415 | HHVet int not NULL, 416 | HHChronic int not NULL, 417 | HHDisability int not NULL, 418 | HHFleeingDV int not NULL, 419 | HoHRaceEthnicity int not NULL, 420 | HHAdultAge int not NULL, 421 | HHParent int not NULL, 422 | AC3Plus int not NULL, 423 | SystemPath int not NULL, 424 | ReportID int not NULL 425 | ) 426 | 427 | /* 428 | 2.12 LSACalculated.csv / lsa_Calculated 429 | */ 430 | 431 | if object_id ('lsa_Calculated') is not NULL drop table lsa_Calculated 432 | 433 | create table lsa_Calculated( 434 | Value int not NULL, 435 | Cohort int not NULL, 436 | Universe int not NULL, 437 | HHType int not NULL, 438 | [Population] int not NULL, 439 | SystemPath int not NULL, 440 | ProjectID nvarchar(32), 441 | ReportRow int not NULL, 442 | ReportID int not NULL, 443 | Step nvarchar(10) not NULL 444 | ) 445 | 446 | -------------------------------------------------------------------------------- /03_01a LSA Parameters and Metadata.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 03_01a LSA Parameters and Metadata for AHAR.sql 4 | 5 | FY2024 Changes 6 | -Update dates 7 | -Filename changed to specify that parameters are for an annual report vs a HIC (single day) report 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | The hard-coded values here must be replaced with code to accept actual user-entered parameters 12 | and info specific to the HMIS application. 13 | */ 14 | delete from lsa_Report 15 | 16 | insert into lsa_Report ( 17 | ReportID --system-generated unique identifier for report process 18 | , ReportStart --user-entered start of report period 19 | , ReportEnd --user-entered end of report period 20 | , ReportCoC --user-selected HUD Continuum of Care Code 21 | , SoftwareVendor --name of vendor 22 | , SoftwareName --name of HMIS application 23 | , VendorContact --name of vendor contact 24 | , VendorEmail --email address of vendor contact 25 | , LSAScope --user-selected 1=systemwide, 2=project-focused 3=HIC 26 | , LookbackDate --ReportStart - 7 years 27 | ) 28 | select 29 | right(year(getdate()), 1)*100000000 + cast(format (getdate(),'MMddHHmm') as int) 30 | , '10/1/2023' 31 | , '9/30/2024' 32 | , 'XX-501' 33 | , 'Sample Code Inc.' 34 | , 'LSA Online' 35 | , 'Molly' 36 | , 'molly@squarepegdata.com' 37 | , 1 38 | , dateadd(yyyy, -7, '10/1/2023') 39 | -------------------------------------------------------------------------------- /03_01b LSA Parameters and Metadata for HIC.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 03_01b LSA Parameters and Metadata for HIC.sql 4 | 5 | FY2024 Changes 6 | -New file with HIC parameters / new LSAScope value of 3 to indicate HIC 7 | 8 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 9 | 10 | The hard-coded values here must be replaced with code to accept actual user-entered parameters 11 | and info specific to the HMIS application. 12 | 13 | If LSAScope=3 (HIC), ReportStart and ReportEnd must be identical. 14 | */ 15 | delete from lsa_Report 16 | 17 | insert into lsa_Report ( 18 | ReportID --system-generated unique identifier for report process 19 | , ReportStart --user-entered start of report period 20 | , ReportEnd --user-entered end of report period 21 | , ReportCoC --user-selected HUD Continuum of Care Code 22 | , SoftwareVendor --name of vendor 23 | , SoftwareName --name of HMIS application 24 | , VendorContact --name of vendor contact 25 | , VendorEmail --email address of vendor contact 26 | , LSAScope --user-selected 1=systemwide, 2=project-focused 3=HIC 27 | , LookbackDate --ReportStart - 7 years 28 | ) 29 | select 30 | right(year(getdate()), 1)*100000000 + cast(format (getdate(),'MMddHHmm') as int) 31 | , '1/29/2025' 32 | , '1/29/2025' 33 | , 'XX-501' 34 | , 'Sample Code Inc.' 35 | , 'LSA Online' 36 | , 'Molly' 37 | , 'molly@squarepegdata.com' 38 | , 3 39 | , dateadd(yyyy, -7, '1/29/2025') 40 | -------------------------------------------------------------------------------- /03_02 to 03_06 HMIS Households and Enrollments.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 03_02 to 03_06 HMIS Households and Enrollments.sql 4 | 5 | FY2024 Changes 6 | 7 | 3.2 - Set ReportEnd = ReportStart if LSAScope = HIC 8 | - Set Exit and Point-in-Time Cohort dates only if LSAScope <> HIC 9 | 3.3 - Adjust entry/exit dates to align with period of projects' HMIS participation if the dates conflict 10 | and limit reported bednights to periods of HMIS participation 11 | 3.3.1 - Operating end dates and HMIS participation end dates are considered inactive; enrollment dates 12 | and bed nights must be < operating/HMIS end dates in order to be relevant. 13 | 14 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 15 | 16 | 17 | 3.2 Cohort Dates 18 | */ 19 | 20 | if (select LSAScope from lsa_Report) = 3 21 | begin 22 | update lsa_Report set ReportEnd = ReportStart 23 | end -- END IF LSAScope = HIC 24 | 25 | truncate table tlsa_CohortDates 26 | 27 | insert into tlsa_CohortDates (Cohort, CohortStart, CohortEnd, LookbackDate, ReportID) 28 | select 1, rpt.ReportStart, rpt.ReportEnd, rpt.LookbackDate, rpt.ReportID 29 | from lsa_Report rpt 30 | 31 | if (select LSAScope from lsa_Report) <> 3 32 | begin 33 | 34 | insert into tlsa_CohortDates (Cohort, CohortStart, CohortEnd, LookbackDate, ReportID) 35 | select 0, rpt.ReportStart, 36 | case when dateadd(mm, -6, rpt.ReportEnd) <= rpt.ReportStart 37 | then rpt.ReportEnd 38 | else dateadd(mm, -6, rpt.ReportEnd) end 39 | , rpt.LookbackDate 40 | , rpt.ReportID 41 | from lsa_Report rpt 42 | 43 | insert into tlsa_CohortDates (Cohort, CohortStart, CohortEnd, LookbackDate, ReportID) 44 | select -1, dateadd(yyyy, -1, rpt.ReportStart) 45 | , dateadd(yyyy, -1, rpt.ReportEnd) 46 | , rpt.LookbackDate 47 | , rpt.ReportID 48 | from lsa_Report rpt 49 | 50 | insert into tlsa_CohortDates (Cohort, CohortStart, CohortEnd, LookbackDate, ReportID) 51 | select -2, dateadd(yyyy, -2, rpt.ReportStart) 52 | , dateadd(yyyy, -2, rpt.ReportEnd) 53 | , rpt.LookbackDate 54 | , rpt.ReportID 55 | from lsa_Report rpt 56 | 57 | insert into tlsa_CohortDates (Cohort, CohortStart, CohortEnd, LookbackDate, ReportID) 58 | select distinct case cal.mm 59 | when 10 then 10 60 | when 1 then 11 61 | when 4 then 12 62 | else 13 end 63 | , cal.theDate 64 | , cal.theDate 65 | , rpt.LookbackDate 66 | , rpt.ReportID 67 | from lsa_Report rpt 68 | inner join ref_Calendar cal 69 | on cal.theDate between rpt.ReportStart and rpt.ReportEnd 70 | where (cal.mm = 10 and cal.dd = 31 and cal.yyyy = year(rpt.ReportStart)) 71 | or (cal.mm = 1 and cal.dd = 31 and cal.yyyy = year(rpt.ReportEnd)) 72 | or (cal.mm = 4 and cal.dd = 30 and cal.yyyy = year(rpt.ReportEnd)) 73 | or (cal.mm = 7 and cal.dd = 31 and cal.yyyy = year(rpt.ReportEnd)) 74 | 75 | end -- END IF LSASCOPE <> HIC 76 | 77 | /* 78 | 3.3 HMIS HouseholdIDs 79 | */ 80 | truncate table tlsa_HHID 81 | 82 | insert into tlsa_HHID ( 83 | HouseholdID, HoHID, EnrollmentID 84 | , ProjectID, LSAProjectType 85 | , EntryDate 86 | , MoveInDate 87 | , ExitDate 88 | , LastBedNight 89 | , Step) 90 | select 91 | HouseholdID, HoHID, EnrollmentID, ProjectID, LSAProjectType 92 | , case 93 | -- nbn EntryDate must = FirstBedNight 94 | when LSAProjectType = 1 then FirstBedNight 95 | -- no adjustment as long as the entry date occurs while the project is operating & participating in HMIS 96 | when EntryDate >= pStart then EntryDate 97 | -- otherwise, adjust to the later of HMIS/OperatingStart 98 | else pStart end 99 | , case 100 | -- select null if recorded Move-In Date is null, not relevant, or not valid 101 | when core.MoveInDate is null 102 | or core.MoveInDate > rpt.ReportEnd 103 | or LSAProjectType not in (3,13,15) 104 | or core.MoveInDate < EntryDate 105 | or core.MoveInDate >= pEnd 106 | or core.MoveInDate > ExitDate 107 | or (core.MoveInDate = ExitDate and LSAProjectType = 3) 108 | then null 109 | -- no adjustment as long as the valid MoveInDate occurs while the project is operating & participating in HMIS 110 | when core.MoveInDate >= pStart then core.MoveInDate 111 | else pStart end 112 | , case 113 | when LSAProjectType = 1 and LastBednight = rpt.ReportEnd then null 114 | when LSAProjectType = 1 and ExitDate < rpt.ReportEnd then dateadd(dd, 1, LastBednight) 115 | when dateadd(dd, 90, LastBednight) <= rpt.ReportEnd then dateadd(dd, 1, LastBednight) 116 | -- When RRH MoveInDate = ExitDate, uses an effective ExitDate of MoveIn + 1 day so that subsequent 117 | -- sections can use the same logic for RRH and PSH. 118 | when LSAProjectType in (13,15) and core.MoveInDate = ExitDate and (pEnd is null or core.MoveInDate < pEnd) and ExitDate = rpt.ReportEnd then NULL 119 | when LSAProjectType in (13,15) and core.MoveInDate = ExitDate and (pEnd is null or core.MoveInDate < pEnd) and ExitDate < rpt.ReportEnd then dateadd(dd, 1, ExitDate) 120 | when pEnd is not null and (ExitDate is null or ExitDate >= pEnd) then pEnd 121 | when ExitDate > rpt.ReportEnd then null 122 | else ExitDate end 123 | , LastBednight 124 | , '3.3.1' 125 | from 126 | lsa_Report rpt 127 | inner join 128 | (select hoh.HouseholdID, hoh.PersonalID as HoHID, hoh.EnrollmentID 129 | , hoh.ProjectID, p.LSAProjectType 130 | , hoh.EntryDate, hoh.MoveInDate, hx.ExitDate, min(bn.BedNightDate) as FirstBedNight, max(bn.BedNightDate) as LastBedNight 131 | , case when part.HMISStart >= p.OperatingStart then part.HMISStart 132 | else p.OperatingStart end as pStart 133 | , case when part.HMISEnd <= p.OperatingEnd or (part.HMISEnd is not null and p.OperatingEnd is null) then part.HMISEnd 134 | when part.HMISEnd > p.OperatingEnd or (part.HMISEnd is null and p.OperatingEnd is not null) then p.OperatingEnd 135 | else null end as pEnd 136 | , rpt.LookbackDate, rpt.ReportEnd 137 | from hmis_Enrollment hoh 138 | inner join lsa_Report rpt on rpt.ReportEnd >= hoh.EntryDate and rpt.ReportCoC = hoh.EnrollmentCoC 139 | inner join ( 140 | select hp.ProjectID 141 | -- Code here and elsewhere 142 | -- Uses LSAProjectType = 13 when ProjectType = 13 and RRHSubType = 2 (RRH: Housing with or without services) 143 | -- and LSAProjectType = 15 when ProjectType = 13 and RRHSubType = 1 (RRH: Services Only) 144 | , case when hp.ProjectType = 13 and hp.RRHSubType = 1 then 15 else hp.ProjectType end as LSAProjectType 145 | , hp.OperatingStartDate as OperatingStart 146 | -- Selecting null if Operating End > Cohort End so not necessary to specify over and over again 147 | -- "OperatingEndDate is null or OperatingEndDate > ReportEnd" 148 | , case when hp.OperatingEndDate <= cd.CohortEnd then hp.OperatingEndDate else null end as OperatingEnd 149 | from hmis_Project hp 150 | inner join hmis_Organization ho on ho.OrganizationID = hp.OrganizationID 151 | inner join tlsa_CohortDates cd on cd.Cohort = 1 152 | where hp.DateDeleted is null 153 | and hp.ContinuumProject = 1 154 | and ho.VictimServiceProvider = 0 155 | and hp.ProjectType in (0,1,2,3,8,13) 156 | and (hp.ProjectType <> 13 or hp.RRHSubType in (1,2)) 157 | and hp.OperatingStartDate <= cd.CohortEnd 158 | and (hp.OperatingEndDate is null 159 | or (hp.OperatingEndDate > hp.OperatingStartDate and hp.OperatingEndDate > cd.LookbackDate)) 160 | ) p on p.ProjectID = hoh.ProjectID 161 | -- Some part of the enrollment must occur during a period of HMIS participation for the project 162 | inner join ( 163 | select hp.HMISParticipationID, hp.ProjectID, hp.HMISParticipationStatusStartDate as HMISStart 164 | -- Selecting null if HMIS End > Cohort End so not necessary to specify over and over again 165 | -- "HMISParticipationStatusEndDate is null or HMISParticipationStatusEndDate > ReportEnd" 166 | -- Also using HMISStart and HMISEnd aliases for obvious reasons 167 | , case when hp.HMISParticipationStatusEndDate > (select ReportEnd from lsa_Report) then null else hp.HMISParticipationStatusEndDate end as HMISEnd 168 | from hmis_HMISParticipation hp 169 | ) part on part.ProjectID = hoh.ProjectID 170 | left outer join hmis_Exit hx on hx.EnrollmentID = hoh.EnrollmentID 171 | and (hx.ExitDate <= p.OperatingEnd or p.OperatingEnd is null) 172 | and (hx.ExitDate <= part.HMISEnd or part.HMISEnd is null) 173 | and hx.DateDeleted is null 174 | left outer join hmis_Enrollment hohCheck on hohCheck.HouseholdID = hoh.HouseholdID 175 | and hohCheck.RelationshipToHoH = 1 and hohCheck.EnrollmentID <> hoh.EnrollmentID 176 | and hohCheck.DateDeleted is null 177 | left outer join (select svc.EnrollmentID, svc.DateProvided as BedNightDate 178 | from hmis_Services svc 179 | where svc.RecordType = 200 and svc.DateDeleted is null 180 | ) bn on bn.EnrollmentID = hoh.EnrollmentID and p.LSAProjectType = 1 181 | and bn.BedNightDate >= part.HMISStart 182 | and bn.BedNightDate >= p.OperatingStart 183 | and bn.BedNightDate >= rpt.LookbackDate 184 | and bn.BedNightDate >= hoh.EntryDate 185 | and bn.BedNightDate <= rpt.ReportEnd 186 | and (bn.BedNightDate < hx.ExitDate or hx.ExitDate is null) 187 | and (bn.BedNightDate < part.HMISEnd or part.HMISEnd is null) 188 | and (bn.BedNightDate < p.OperatingEnd or p.OperatingEnd is null) 189 | where hoh.DateDeleted is null 190 | and hoh.RelationshipToHoH = 1 191 | and hohCheck.EnrollmentID is null 192 | and (hoh.EntryDate < p.OperatingEnd or p.OperatingEnd is null) 193 | and (hx.ExitDate is null or 194 | ( hx.ExitDate > rpt.LookbackDate 195 | and hx.ExitDate > hoh.EntryDate 196 | and hx.ExitDate > p.OperatingStart 197 | and hx.ExitDate > part.HMISStart 198 | ) 199 | ) 200 | and part.HMISParticipationID = (select top 1 hp1.HMISParticipationID 201 | from hmis_HMISParticipation hp1 202 | where hp1.ProjectID = hoh.ProjectID 203 | and hp1.HMISParticipationType = 1 204 | and (hp1.HMISParticipationStatusEndDate is null 205 | or (hp1.HMISParticipationStatusEndDate > (select LookbackDate from lsa_Report) and hp1.HMISParticipationStatusEndDate > hoh.EntryDate) 206 | ) 207 | and hp1.HMISParticipationStatusStartDate <= (select ReportEnd from lsa_Report) 208 | and (hx.ExitDate > hp1.HMISParticipationStatusStartDate or hx.ExitDate is null) 209 | and hp1.DateDeleted is null 210 | order by hp1.HMISParticipationStatusStartDate desc) 211 | group by hoh.HouseholdID, hoh.PersonalID, hoh.EnrollmentID 212 | , hoh.ProjectID, p.LSAProjectType 213 | , hoh.EntryDate, hoh.MoveInDate, hx.ExitDate 214 | , part.HMISStart, part.HMISEnd, p.OperatingStart, p.OperatingEnd 215 | , rpt.LookbackDate, rpt.ReportEnd 216 | ) core on core.EntryDate <= rpt.ReportEnd 217 | where core.LSAProjectType <> 1 or core.LastBedNight is not null 218 | 219 | update hhid 220 | set hhid.ExitDest = case 221 | when hhid.ExitDate is null then -1 222 | when hx.Destination is null or 223 | hx.Destination in (17,30,99) or 224 | (hx.ExitDate <> hhid.ExitDate 225 | and (hhid.MoveInDate is NULL or hhid.MoveInDate <> hx.ExitDate)) then 99 226 | when hx.Destination in (8,9) then 98 227 | when hx.Destination = 435 and hx.DestinationSubsidyType is null then 99 228 | when hx.Destination = 435 then hx.DestinationSubsidyType 229 | else hx.Destination end 230 | , hhid.Step = '3.3.2' 231 | from tlsa_HHID hhid 232 | left outer join hmis_Exit hx on hx.EnrollmentID = hhid.EnrollmentID 233 | and hx.DateDeleted is null 234 | 235 | /* 236 | 3.4 HMIS Client Enrollments 237 | */ 238 | truncate table tlsa_Enrollment 239 | 240 | --all project types except ES night-by-night 241 | insert into tlsa_Enrollment 242 | (EnrollmentID, PersonalID, HouseholdID 243 | , RelationshipToHoH 244 | , ProjectID, LSAProjectType 245 | , EntryDate, ExitDate 246 | , DisabilityStatus 247 | , Step) 248 | select distinct hn.EnrollmentID, hn.PersonalID, hn.HouseholdID 249 | , hn.RelationshipToHoH 250 | , hhid.ProjectID, hhid.LSAProjectType 251 | , case when hhid.EntryDate > hn.EntryDate then hhid.EntryDate else hn.EntryDate end 252 | , case when hx.ExitDate >= hhid.ExitDate then hhid.ExitDate 253 | when hx.ExitDate is NULL and hhid.ExitDate is not NULL then hhid.ExitDate 254 | when hhid.LSAProjectType in (13,15) and hhid.MoveInDate = hx.ExitDate and hx.ExitDate = rpt.ReportEnd then NULL 255 | when hhid.LSAProjectType in (13,15) and hhid.MoveInDate = hx.ExitDate then dateadd(dd, 1, hx.ExitDate) 256 | else hx.ExitDate end 257 | , case when hn.DisablingCondition in (0,1) then hn.DisablingCondition 258 | else null end 259 | , '3.4.1' 260 | from tlsa_HHID hhid 261 | inner join hmis_Enrollment hn on hn.HouseholdID = hhid.HouseholdID 262 | and hn.DateDeleted is NULL 263 | inner join lsa_Report rpt on rpt.ReportEnd >= hn.EntryDate 264 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 265 | and hx.ExitDate <= rpt.ReportEnd 266 | and hx.DateDeleted is null 267 | where hhid.LSAProjectType in (0,2,3,8,13,15) 268 | and hn.RelationshipToHoH in (1,2,3,4,5) 269 | and hn.EntryDate <= isnull(hhid.ExitDate, rpt.ReportEnd) 270 | and (hx.ExitDate is null or 271 | (hx.ExitDate > hhid.EntryDate and hx.ExitDate > rpt.LookbackDate 272 | and hx.ExitDate > hn.EntryDate)) 273 | 274 | -- ES night-by-night 275 | insert into tlsa_Enrollment 276 | (EnrollmentID, PersonalID, HouseholdID 277 | , RelationshipToHoH 278 | , ProjectID, LSAProjectType 279 | , EntryDate, ExitDate 280 | , LastBednight 281 | , DisabilityStatus 282 | , Step) 283 | select distinct svc.EnrollmentID, nbn.PersonalID, nbn.HouseholdID 284 | , nbn.RelationshipToHoH 285 | , hhid.ProjectID, hhid.LSAProjectType 286 | , min(svc.DateProvided) as EntryDate 287 | , case when nbnx.ExitDate is null and hhid.ExitDate is null and dateadd(dd, 90, max(svc.DateProvided)) > rpt.ReportEnd then null 288 | else dateadd(dd, 1, max(svc.DateProvided)) end as ExitDate 289 | , max(svc.DateProvided) as LastBednight 290 | , case when nbn.DisablingCondition in (0,1) then nbn.DisablingCondition else null end 291 | , '3.4.2' 292 | from hmis_Services svc 293 | inner join hmis_Enrollment nbn on nbn.EnrollmentID = svc.EnrollmentID and svc.DateProvided >= nbn.EntryDate 294 | and nbn.DateDeleted is null 295 | inner join tlsa_HHID hhid on hhid.HouseholdID = nbn.HouseholdID and svc.DateProvided >= hhid.EntryDate 296 | and (hhid.ExitDate is null or svc.DateProvided < hhid.ExitDate) 297 | left outer join hmis_Exit nbnx on nbnx.EnrollmentID = nbn.EnrollmentID and nbnx.DateDeleted is null 298 | inner join lsa_Report rpt on svc.DateProvided between rpt.LookbackDate and rpt.ReportEnd 299 | where hhid.LSAProjectType = 1 300 | and svc.RecordType = 200 and svc.DateDeleted is null 301 | and svc.DateProvided >= nbn.EntryDate 302 | and svc.DateProvided >= rpt.LookbackDate 303 | and (nbnx.ExitDate is null or svc.DateProvided < nbnx.ExitDate) 304 | and nbn.RelationshipToHoH in (1,2,3,4,5) 305 | group by svc.EnrollmentID, nbn.PersonalID, nbn.HouseholdID 306 | , nbn.RelationshipToHoH 307 | , hhid.ProjectID, hhid.LSAProjectType 308 | , case when nbn.DisablingCondition in (0,1) then nbn.DisablingCondition else null end 309 | , nbnx.ExitDate, hhid.ExitDate, rpt.ReportEnd 310 | 311 | 312 | update n 313 | set n.MoveInDate = case when hhid.MoveInDate < n.EntryDate then n.EntryDate 314 | when hhid.MoveInDate > n.ExitDate then NULL 315 | when hhid.MoveInDate = n.ExitDate and 316 | (hhid.ExitDate is NULL or hhid.ExitDate > n.ExitDate) then NULL 317 | else hhid.MoveInDate end 318 | , Step = '3.4.3' 319 | from tlsa_Enrollment n 320 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID and hhid.LSAProjectType in (3,13,15) 321 | 322 | update n 323 | set n.DVStatus = dv.DVStat 324 | , n.Step = '3.4.4' 325 | from tlsa_Enrollment n 326 | left outer join (select dv.EnrollmentID, 327 | min(case when dv.DomesticViolenceSurvivor = 1 and dv.CurrentlyFleeing = 1 then 1 328 | when dv.DomesticViolenceSurvivor = 1 and dv.CurrentlyFleeing = 0 then 2 329 | when dv.DomesticViolenceSurvivor = 1 then 3 330 | when dv.DomesticViolenceSurvivor = 0 then 10 331 | else 98 end) as DVStat 332 | from hmis_HealthAndDV dv 333 | inner join lsa_Report rpt on rpt.ReportEnd >= dv.InformationDate 334 | inner join tlsa_Enrollment n on n.EnrollmentID = dv.EnrollmentID and dv.InformationDate >= n.EntryDate 335 | and (n.ExitDate is null or dv.InformationDate <= n.ExitDate) 336 | group by dv.EnrollmentID) dv on n.EnrollmentID = dv.EnrollmentID 337 | 338 | /* 339 | 3.5 Enrollment Ages - Active and Exit 340 | NOTE: EntryAge is included in the 3.4 insert statement 341 | */ 342 | 343 | update n 344 | set n.EntryAge = case when c.DOBDataQuality in (8,9) then 98 345 | when c.DOB is null 346 | or c.DOB = '1/1/1900' 347 | or c.DOB > n.EntryDate 348 | or (n.RelationshipToHoH = 1 and c.DOB = n.EntryDate) 349 | or DATEADD(yy, 105, c.DOB) <= n.EntryDate 350 | or c.DOBDataQuality is null 351 | or c.DOBDataQuality not in (1,2) then 99 352 | when DATEADD(yy, 65, c.DOB) <= n.EntryDate then 65 353 | when DATEADD(yy, 55, c.DOB) <= n.EntryDate then 64 354 | when DATEADD(yy, 45, c.DOB) <= n.EntryDate then 54 355 | when DATEADD(yy, 35, c.DOB) <= n.EntryDate then 44 356 | when DATEADD(yy, 25, c.DOB) <= n.EntryDate then 34 357 | when DATEADD(yy, 22, c.DOB) <= n.EntryDate then 24 358 | when DATEADD(yy, 18, c.DOB) <= n.EntryDate then 21 359 | when DATEADD(yy, 6, c.DOB) <= n.EntryDate then 17 360 | when DATEADD(yy, 3, c.DOB) <= n.EntryDate then 5 361 | when DATEADD(yy, 1, c.DOB) <= n.EntryDate then 2 362 | else 0 end 363 | , n.Step = '3.5.1' 364 | from tlsa_Enrollment n 365 | inner join hmis_Client c on c.PersonalID = n.PersonalID 366 | 367 | update n 368 | set n.EntryAge = 99, n.Step = '3.5.2' 369 | from tlsa_Enrollment n 370 | inner join tlsa_Enrollment DOBIssue on DOBIssue.PersonalID = n.PersonalID 371 | and DOBIssue.EntryAge = 99 372 | 373 | update n 374 | set n.ActiveAge = case when n.ExitDate < rpt.ReportStart 375 | or n.EntryDate >= rpt.ReportStart 376 | or n.EntryAge in (98,99) then n.EntryAge 377 | when DATEADD(yy, 65, c.DOB) <= rpt.ReportStart then 65 378 | when DATEADD(yy, 55, c.DOB) <= rpt.ReportStart then 64 379 | when DATEADD(yy, 45, c.DOB) <= rpt.ReportStart then 54 380 | when DATEADD(yy, 35, c.DOB) <= rpt.ReportStart then 44 381 | when DATEADD(yy, 25, c.DOB) <= rpt.ReportStart then 34 382 | when DATEADD(yy, 22, c.DOB) <= rpt.ReportStart then 24 383 | when DATEADD(yy, 18, c.DOB) <= rpt.ReportStart then 21 384 | when DATEADD(yy, 6, c.DOB) <= rpt.ReportStart then 17 385 | when DATEADD(yy, 3, c.DOB) <= rpt.ReportStart then 5 386 | when DATEADD(yy, 1, c.DOB) <= rpt.ReportStart then 2 387 | else 0 end 388 | , n.Step = '3.5.3' 389 | from lsa_Report rpt 390 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 391 | inner join hmis_Client c on c.PersonalID = n.PersonalID 392 | 393 | update n 394 | set n.Exit1Age = case when n.EntryDate >= cd.CohortStart 395 | or (n.ExitDate not between cd.CohortStart and cd.CohortEnd or n.ExitDate is null) 396 | or n.EntryAge in (98,99) then n.EntryAge 397 | when DATEADD(yy, 65, c.DOB) <= cd.CohortStart then 65 398 | when DATEADD(yy, 55, c.DOB) <= cd.CohortStart then 64 399 | when DATEADD(yy, 45, c.DOB) <= cd.CohortStart then 54 400 | when DATEADD(yy, 35, c.DOB) <= cd.CohortStart then 44 401 | when DATEADD(yy, 25, c.DOB) <= cd.CohortStart then 34 402 | when DATEADD(yy, 22, c.DOB) <= cd.CohortStart then 24 403 | when DATEADD(yy, 18, c.DOB) <= cd.CohortStart then 21 404 | when DATEADD(yy, 6, c.DOB) <= cd.CohortStart then 17 405 | when DATEADD(yy, 3, c.DOB) <= cd.CohortStart then 5 406 | when DATEADD(yy, 1, c.DOB) <= cd.CohortStart then 2 407 | else 0 end 408 | , n.Step = '3.5.4' 409 | from tlsa_Enrollment n 410 | inner join tlsa_CohortDates cd on cd.Cohort = -1 411 | inner join hmis_Client c on c.PersonalID = n.PersonalID 412 | 413 | update n 414 | set n.Exit2Age = case when n.EntryDate >= cd.CohortStart 415 | or (n.ExitDate not between cd.CohortStart and cd.CohortEnd or n.ExitDate is null) 416 | or n.EntryAge in (98,99) then n.EntryAge 417 | when DATEADD(yy, 65, c.DOB) <= cd.CohortStart then 65 418 | when DATEADD(yy, 55, c.DOB) <= cd.CohortStart then 64 419 | when DATEADD(yy, 45, c.DOB) <= cd.CohortStart then 54 420 | when DATEADD(yy, 35, c.DOB) <= cd.CohortStart then 44 421 | when DATEADD(yy, 25, c.DOB) <= cd.CohortStart then 34 422 | when DATEADD(yy, 22, c.DOB) <= cd.CohortStart then 24 423 | when DATEADD(yy, 18, c.DOB) <= cd.CohortStart then 21 424 | when DATEADD(yy, 6, c.DOB) <= cd.CohortStart then 17 425 | when DATEADD(yy, 3, c.DOB) <= cd.CohortStart then 5 426 | when DATEADD(yy, 1, c.DOB) <= cd.CohortStart then 2 427 | else 0 end 428 | , n.Step = '3.5.5' 429 | from tlsa_Enrollment n 430 | inner join tlsa_CohortDates cd on cd.Cohort = -2 431 | inner join hmis_Client c on c.PersonalID = n.PersonalID 432 | 433 | --NOTE: The logic for HIV/SMI/SUD columns is described in specs section 5.4; this is occurring in the code here 434 | -- because it made a massive difference in the speed with which the code in section 5.4 runs. 435 | update n 436 | set n.HIV = 1, n.Step = '3.5.6' 437 | from tlsa_Enrollment n 438 | inner join hmis_Disabilities d on d.EnrollmentID = n.EnrollmentID and d.DisabilityType = 8 and d.DisabilityResponse = 1 439 | where n.ActiveAge between 18 and 65 and d.InformationDate <= (select ReportEnd from lsa_Report) 440 | 441 | update n 442 | set n.SMI = 1, n.Step = '3.5.7' 443 | from tlsa_Enrollment n 444 | inner join hmis_Disabilities d on d.EnrollmentID = n.EnrollmentID and d.DisabilityType = 9 and d.DisabilityResponse = 1 445 | and d.IndefiniteAndImpairs = 1 446 | where n.ActiveAge between 18 and 65 and d.InformationDate <= (select ReportEnd from lsa_Report) 447 | 448 | update n 449 | set n.SUD = 1, n.Step = '3.5.8' 450 | from tlsa_Enrollment n 451 | inner join hmis_Disabilities d on d.EnrollmentID = n.EnrollmentID and d.DisabilityType = 10 and d.DisabilityResponse in (1,2,3) 452 | and d.IndefiniteAndImpairs = 1 453 | where n.ActiveAge between 18 and 65 and d.InformationDate <= (select ReportEnd from lsa_Report) 454 | 455 | 456 | /* 457 | 3.6 Household Types 458 | */ 459 | 460 | -- Note: Code here and elsewhere uses 'between 18 and 65' instead of 'between 21 and 65' because the output 461 | -- is the same (there are no values of 18, 19, or 20) and it is easier to understand without consulting 462 | -- the LSA Dictionary. 463 | 464 | update hhid 465 | set hhid.EntryHHType = case when hh.hh = 100 then 1 466 | when hh.hh in (110, 111) then 2 467 | when hh.hh = 10 then 3 468 | else 99 end 469 | , hhid.Step = '3.6.1' 470 | from tlsa_HHID hhid 471 | inner join (select HouseholdID 472 | , sum(distinct case when n.EntryAge between 18 and 65 then 100 473 | when n.EntryAge < 18 then 10 474 | else 1 end) as hh 475 | from tlsa_Enrollment n 476 | group by HouseholdID) hh on hh.HouseholdID = hhid.HouseholdID 477 | 478 | 479 | update hhid 480 | set hhid.ActiveHHType = case when hhid.ExitDate < cd.CohortStart 481 | or hhid.EntryDate >= cd.CohortStart then hhid.EntryHHType 482 | when hh.hh = 100 then 1 483 | when hh.hh in (110, 111) then 2 484 | when hh.hh = 10 then 3 485 | else 99 end 486 | , hhid.Step = '3.6.2' 487 | from tlsa_HHID hhid 488 | inner join tlsa_CohortDates cd on cd.Cohort = 1 489 | left outer join (select HouseholdID 490 | , sum(distinct case when n.ActiveAge between 18 and 65 then 100 491 | when n.ActiveAge < 18 then 10 492 | else 1 end) as hh 493 | from tlsa_Enrollment n 494 | inner join tlsa_CohortDates cd on cd.Cohort = 1 495 | where n.ExitDate is null or n.ExitDate >= cd.CohortStart 496 | group by HouseholdID) hh on hh.HouseholdID = hhid.HouseholdID 497 | 498 | update hhid 499 | set hhid.Exit1HHType = case when hhid.ExitDate < cd.CohortStart 500 | or hhid.EntryDate >= cd.CohortStart then hhid.EntryHHType 501 | when hh.hh = 100 then 1 502 | when hh.hh in (110, 111) then 2 503 | when hh.hh = 10 then 3 504 | else 99 end 505 | , hhid.Step = '3.6.3' 506 | from tlsa_HHID hhid 507 | inner join tlsa_CohortDates cd on cd.Cohort = -1 508 | left outer join (select HouseholdID 509 | , sum(distinct case when n.Exit1Age between 18 and 65 then 100 510 | when n.Exit1Age < 18 then 10 511 | else 1 end) as hh 512 | from tlsa_Enrollment n 513 | inner join tlsa_CohortDates cd on cd.Cohort = -1 514 | where n.ExitDate is null or n.ExitDate >= cd.CohortStart 515 | group by HouseholdID) hh on hh.HouseholdID = hhid.HouseholdID 516 | 517 | update hhid 518 | set hhid.Exit2HHType = case when hhid.ExitDate < cd.CohortStart 519 | or hhid.EntryDate >= cd.CohortStart then hhid.EntryHHType 520 | when hh.hh = 100 then 1 521 | when hh.hh in (110, 111) then 2 522 | when hh.hh = 10 then 3 523 | else 99 end 524 | , hhid.Step = '3.6.4' 525 | from tlsa_HHID hhid 526 | inner join tlsa_CohortDates cd on cd.Cohort = -2 527 | left outer join (select HouseholdID 528 | , sum(distinct case when n.Exit2Age between 18 and 65 then 100 529 | when n.Exit2Age < 18 then 10 530 | else 1 end) as hh 531 | from tlsa_Enrollment n 532 | inner join tlsa_CohortDates cd on cd.Cohort = -2 533 | where n.ExitDate is null or n.ExitDate >= cd.CohortStart 534 | group by HouseholdID) hh on hh.HouseholdID = hhid.HouseholdID 535 | -------------------------------------------------------------------------------- /04_01 Get Project Records.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 04_01 Get Project Records.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | 4.1 Get Project Records for Export 12 | Export records for continuum ES entry/exit (0), ES night-by-night (1), 13 | SH (8), TH (2), RRH (13), PSH (3), and OPH (9 or 10) projects active in the report period 14 | and/or in the seven years prior to the report period. 15 | 16 | NOTE: If used in production, must be modified to accept user-selected ProjectIDs as 17 | parameters when LSAScope = 2. 18 | */ 19 | delete from lsa_Project 20 | 21 | insert into lsa_Project 22 | (ProjectID, OrganizationID, ProjectName 23 | , OperatingStartDate, OperatingEndDate 24 | , ContinuumProject, ProjectType, HousingType, RRHSubType 25 | , ResidentialAffiliation, TargetPopulation 26 | , HOPWAMedAssistedLivingFac 27 | , DateCreated, DateUpdated, ExportID) 28 | select distinct 29 | hp.ProjectID, hp.OrganizationID, left(hp.ProjectName, 200) 30 | , format(hp.OperatingStartDate, 'yyyy-MM-dd') 31 | , case when hp.OperatingEndDate is not null then format(hp.OperatingEndDate, 'yyyy-MM-dd') else null end 32 | , hp.ContinuumProject, hp.ProjectType 33 | , case when hp.RRHSubType = 1 then null else hp.HousingType end 34 | , case when hp.ProjectType = 13 then hp.RRHSubType else null end 35 | , case when hp.RRHSubType = 1 then hp.ResidentialAffiliation else null end 36 | , hp.TargetPopulation 37 | , hp.HOPWAMedAssistedLivingFac 38 | , format(hp.DateCreated, 'yyyy-MM-dd HH:mm:ss') 39 | , format(hp.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 40 | , rpt.ReportID 41 | from hmis_Project hp 42 | inner join hmis_ProjectCoC coc on coc.ProjectID = hp.ProjectID 43 | and coc.DateDeleted is null 44 | inner join lsa_Report rpt on rpt.ReportCoC = coc.CoCCode 45 | where hp.DateDeleted is null 46 | and hp.ContinuumProject = 1 47 | and hp.ProjectType in (0,1,2,3,8,9,10,13) 48 | and (hp.OperatingEndDate is null 49 | or (hp.OperatingEndDate > rpt.LookbackDate 50 | and hp.OperatingEndDate > hp.OperatingStartDate) 51 | ) 52 | -------------------------------------------------------------------------------- /04_02 to 04_08 Get Other PDDEs.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 04_02 to 04_08 Get Other PDDEs.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | 4.2 Get Organization Records for Export 12 | Export organization records for all projects selected in 4.1. 13 | Organization.csv must have exactly one Organization record for each 14 | OrganizationID in Project.csv 15 | */ 16 | 17 | delete from lsa_Organization 18 | 19 | insert into lsa_Organization 20 | (OrganizationID, OrganizationName 21 | , VictimServiceProvider 22 | , DateCreated, DateUpdated, ExportID) 23 | select distinct ho.OrganizationID 24 | , left(ho.OrganizationName, 200) 25 | , ho.VictimServiceProvider 26 | , format(ho.DateCreated, 'yyyy-MM-dd HH:mm:ss') 27 | , format(ho.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 28 | , lp.ExportID 29 | from hmis_Organization ho 30 | inner join lsa_Project lp on lp.OrganizationID = ho.OrganizationID 31 | where ho.DateDeleted is null 32 | 33 | /* 34 | 4.3 Get Funder Records for Export 35 | Get records for project funders with grants active in the report period. 36 | Funder.csv must have at least one Funder record for each ProjectID 37 | in Project.csv where OperatingEndDate is NULL or > ReportStart. 38 | */ 39 | 40 | delete from lsa_Funder 41 | 42 | insert into lsa_Funder 43 | (FunderID, ProjectID, Funder, OtherFunder 44 | , StartDate, EndDate 45 | , DateCreated, DateUpdated, ExportID) 46 | select distinct hf.FunderID, hf.ProjectID, hf.Funder, hf.OtherFunder 47 | , format(hf.StartDate, 'yyyy-MM-dd') 48 | , case when hf.EndDate is not null then format(hf.EndDate, 'yyyy-MM-dd') else null end 49 | , format(hf.DateCreated, 'yyyy-MM-dd HH:mm:ss') 50 | , format(hf.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 51 | , lp.ExportID 52 | from hmis_Funder hf 53 | inner join lsa_Project lp on lp.ProjectID = hf.ProjectID 54 | inner join lsa_Report rpt on cast(lp.ExportID as int) = rpt.ReportID 55 | where hf.DateDeleted is null 56 | and (hf.EndDate is null 57 | or (hf.EndDate >= rpt.ReportStart 58 | and hf.EndDate > hf.StartDate) 59 | ) 60 | /* 61 | 4.4 Get ProjectCoC Records for Export 62 | ProjectCoC.csv must have exactly one record for each ProjectID in Project.csv 63 | and the CoCCode must match ReportCoC 64 | */ 65 | 66 | delete from lsa_ProjectCoC 67 | 68 | insert into lsa_ProjectCoC ( 69 | ProjectCoCID, ProjectID, CoCCode 70 | , Geocode 71 | , Address1, Address2, City, State 72 | , ZIP, GeographyType 73 | , DateCreated, DateUpdated, ExportID 74 | ) 75 | select hcoc.ProjectCoCID, hcoc.ProjectID, hcoc.CoCCode 76 | , hcoc.Geocode 77 | , left(hcoc.Address1, 100), left(hcoc.Address2, 100), left(hcoc.City, 50), hcoc.State 78 | , left(hcoc.ZIP, 5), hcoc.GeographyType 79 | , format(hcoc.DateCreated, 'yyyy-MM-dd HH:mm:ss') 80 | , format(hcoc.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 81 | , lp.ExportID 82 | from hmis_ProjectCoC hcoc 83 | inner join lsa_Project lp on lp.ProjectID = hcoc.ProjectID 84 | inner join lsa_Report rpt on cast(lp.ExportID as int) = rpt.ReportID 85 | where hcoc.DateDeleted is null 86 | and hcoc.CoCCode = rpt.ReportCoC 87 | 88 | /* 89 | 4.5 Get Inventory Records for Export 90 | Inventory.csv must have at least one record for each ProjectID 91 | in Project.csv where OperatingEndDate is NULL or > ReportStart 92 | and the CoCCode must match ReportCoC. 93 | Note that BedInventory is set up for lsa_Inventory in '02 LSA Output Tables.sql' as a computed column -- 94 | the value MUST equal the sum of the other xBedInventory columns -- so this code 95 | does not select it into lsa_Inventory. 96 | */ 97 | 98 | delete from lsa_Inventory 99 | 100 | insert into lsa_Inventory ( 101 | InventoryID, ProjectID, CoCCode 102 | , HouseholdType, Availability 103 | , UnitInventory 104 | --, BedInventory 105 | , CHVetBedInventory, YouthVetBedInventory, VetBedInventory 106 | , CHYouthBedInventory, YouthBedInventory 107 | , CHBedInventory, OtherBedInventory 108 | , ESBedType 109 | , InventoryStartDate, InventoryEndDate 110 | , DateCreated, DateUpdated, ExportID) 111 | select distinct hi.InventoryID, hi.ProjectID, hi.CoCCode 112 | , hi.HouseholdType 113 | , case when lp.ProjectType in (0,1) then hi.Availability else null end 114 | , hi.UnitInventory 115 | --, hi.BedInventory 116 | , hi.CHVetBedInventory, hi.YouthVetBedInventory, hi.VetBedInventory 117 | , hi.CHYouthBedInventory, hi.YouthBedInventory 118 | , hi.CHBedInventory, hi.OtherBedInventory 119 | , case when lp.ProjectType in (0,1) then hi.ESBedType else null end 120 | , format(hi.InventoryStartDate, 'yyyy-MM-dd') 121 | , case when isdate(cast(hi.InventoryEndDate as datetime)) = 1 then format(hi.InventoryEndDate, 'yyyy-MM-dd') else null end 122 | , format(hi.DateCreated, 'yyyy-MM-dd HH:mm:ss') 123 | , format(hi.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 124 | , lp.ExportID 125 | from hmis_Inventory hi 126 | inner join lsa_Project lp on lp.ProjectID = hi.ProjectID 127 | inner join lsa_Report rpt on cast(lp.ExportID as int) = rpt.ReportID 128 | where hi.DateDeleted is null 129 | and hi.CoCCode = rpt.ReportCoC 130 | and (hi.InventoryEndDate is null 131 | or (hi.InventoryEndDate >= rpt.ReportStart 132 | and hi.InventoryEndDate > hi.InventoryStartDate) 133 | ) 134 | and (lp.ProjectType <> 13 or lp.RRHSubType = 2) 135 | 136 | /* 137 | 4.6 Get HMIS Participation Records for Export 138 | HMISParticipation.csv must have at least one record for each ProjectID 139 | in Project.csv 140 | */ 141 | 142 | delete from lsa_HMISParticipation 143 | 144 | insert into lsa_HMISParticipation ( 145 | HMISParticipationID, ProjectID, 146 | HMISParticipationType, 147 | HMISParticipationStatusStartDate, HMISParticipationStatusEndDate, 148 | DateCreated, DateUpdated, ExportID) 149 | select distinct hp.HMISParticipationID 150 | , hp.ProjectID 151 | , hp.HMISParticipationType 152 | , format(hp.HMISParticipationStatusStartDate, 'yyyy-MM-dd') 153 | , case when isdate(cast(hp.HMISParticipationStatusEndDate as datetime)) = 1 then format(hp.HMISParticipationStatusEndDate, 'yyyy-MM-dd') else null end 154 | , format(hp.DateCreated, 'yyyy-MM-dd HH:mm:ss') 155 | , format(hp.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 156 | , lp.ExportID 157 | from hmis_HMISParticipation hp 158 | inner join lsa_Project lp on lp.ProjectID = hp.ProjectID 159 | where hp.DateDeleted is null 160 | and (lp.OperatingEndDate is null or lp.OperatingEndDate > (select ReportStart from lsa_Report)) 161 | 162 | 163 | /* 164 | 4.7 Get Affiliation Records for Export 165 | Affiliation.csv must have at least one record for each ProjectID 166 | in Project.csv active during the report period where 167 | RRHSubType = 1 and ResidentialAffiliation = 1 168 | */ 169 | 170 | delete from lsa_Affiliation 171 | 172 | insert into lsa_Affiliation ( 173 | AffiliationID, ProjectID, 174 | ResProjectID, 175 | DateCreated, DateUpdated, ExportID) 176 | select distinct a.AffiliationID 177 | , a.ProjectID 178 | , a.ResProjectID 179 | , format(a.DateCreated, 'yyyy-MM-dd HH:mm:ss') 180 | , format(a.DateUpdated, 'yyyy-MM-dd HH:mm:ss') 181 | , lp.ExportID 182 | from hmis_Affiliation a 183 | inner join lsa_Project lp on lp.ProjectID = a.ProjectID 184 | where a.DateDeleted is null 185 | and lp.ProjectType = 13 and lp.RRHSubType = 1 and lp.ResidentialAffiliation = 1 186 | and (lp.OperatingEndDate is null or lp.OperatingEndDate > (select ReportStart from lsa_Report)) -------------------------------------------------------------------------------- /05_01 to 05_11 LSAPerson Records and Demographics.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 05_01 to 05_11 LSAPerson.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode 10 | 11 | 5.1 Identify Active and AHAR HouseholdIDs 12 | */ 13 | 14 | update hhid 15 | set hhid.Active = 1 16 | , hhid.Step = '5.1.1' 17 | from tlsa_HHID HHID 18 | inner join lsa_Report rpt on rpt.ReportEnd >= hhid.EntryDate 19 | inner join lsa_Project p on p.ProjectID = hhid.ProjectID 20 | where (hhid.ExitDate is null or hhid.ExitDate >= rpt.ReportStart) 21 | 22 | update hhid 23 | set hhid.AHAR = 1 24 | , hhid.Step = '5.1.2' 25 | from tlsa_HHID HHID 26 | where hhid.Active = 1 27 | and (hhid.ExitDate is null or hhid.ExitDate > (select ReportStart from lsa_Report)) 28 | and hhid.LSAProjectType not in (3,13,15) 29 | 30 | update hhid 31 | set hhid.AHAR = 1 32 | , hhid.Step = '5.1.3' 33 | from tlsa_HHID HHID 34 | where hhid.Active = 1 35 | and hhid.MoveInDate is not null 36 | and (hhid.ExitDate is null or hhid.ExitDate > (select ReportStart from lsa_Report)) 37 | and hhid.LSAProjectType in (3,13) 38 | 39 | /* 40 | 5.2 Identify Active and AHAR Enrollments 41 | */ 42 | 43 | update n 44 | set n.Active = 1 45 | , n.Step = '5.2.1' 46 | from lsa_Report rpt 47 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 48 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID and hhid.Active = 1 49 | where n.ExitDate is null or n.ExitDate >= rpt.ReportStart 50 | 51 | 52 | update n 53 | set n.AHAR = 1 54 | , n.Step = '5.2.2' 55 | from lsa_Report rpt 56 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 57 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID and hhid.AHAR = 1 58 | where n.Active = 1 59 | and (n.ExitDate is null or n.ExitDate > rpt.ReportStart) 60 | and n.LSAProjectType not in (3,13,15) 61 | 62 | update n 63 | set n.AHAR = 1 64 | , n.Step = '5.2.3' 65 | from lsa_Report rpt 66 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 67 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID and hhid.AHAR = 1 68 | where n.Active = 1 69 | and n.MoveInDate is not null 70 | and (n.ExitDate is null or n.ExitDate > (select ReportStart from lsa_Report)) 71 | and n.LSAProjectType in (3,13) 72 | /* 73 | 5.3 Get Active Clients for LSAPerson 74 | 5.4 LSAPerson Demographics 75 | */ 76 | truncate table tlsa_Person 77 | 78 | insert into tlsa_Person (PersonalID, HoHAdult, 79 | VetStatus, DisabilityStatus, DVStatus, Gender, RaceEthnicity 80 | , ReportID, Step) 81 | select distinct n.PersonalID 82 | , HoHAdult.stat 83 | , case 84 | when HoHAdult.stat not in (1,3) then -1 85 | when c.VeteranStatus in (8,9) then 98 86 | when c.VeteranStatus in (0,1) then c.VeteranStatus 87 | else 99 end 88 | , case 89 | when HoHAdult.stat = 0 then -1 90 | when Disability.stat = 1 then 1 91 | when Disability.stat = 0 then 0 92 | else 99 end 93 | , case 94 | when HoHAdult.stat = 0 then -1 95 | when DV.stat = 10 then 0 96 | when DV.stat is null then 99 97 | else DV.stat end 98 | , case 99 | when c.GenderNone in (8,9) then 98 100 | when c.GenderNone = 99 then 99 101 | when (c.Woman = 1 102 | or c.Man = 1 103 | or c.NonBinary = 1 104 | or c.CulturallySpecific = 1 105 | or c.Transgender = 1 106 | or c.Questioning = 1 107 | or c.DifferentIdentity = 1) then 108 | (select cast ( 109 | (case when c.Man = 1 then '1' else '' end 110 | + case when c.CulturallySpecific = 1 then '2' else '' end 111 | + case when c.DifferentIdentity = 1 then '3' else '' end 112 | + case when c.NonBinary = 1 then '4' else '' end 113 | + case when c.Transgender = 1 then '5' else '' end 114 | + case when c.Questioning = 1 then '6' else '' end 115 | + case when c.Woman = 1 then '0' else '' end 116 | ) as int) 117 | from hmis_Client g 118 | where g.PersonalID = c.PersonalID) 119 | else 99 end 120 | , case 121 | when c.RaceNone in (8,9) then 98 122 | when c.RaceNone = 99 then 99 123 | when (c.AmIndAkNative = 1 124 | or c.Asian = 1 125 | or c.BlackAfAmerican = 1 126 | or c.NativeHIPacific = 1 127 | or c.White = 1 128 | or c.HispanicLatinaeo = 1 129 | or c.MidEastNAfrican = 1) then 130 | (select cast ( 131 | (case when r.AmIndAKNative = 1 then '1' else '' end 132 | + case when r.Asian = 1 then '2' else '' end 133 | + case when r.BlackAfAmerican = 1 then '3' else '' end 134 | + case when r.NativeHIPacific = 1 then '4' else '' end 135 | + case when r.White = 1 then '5' else '' end 136 | + case when r.HispanicLatinaeo = 1 then '6' else '' end 137 | + case when r.MidEastNAfrican = 1 then '7' else '' end) as int) 138 | from hmis_Client r 139 | where r.PersonalID = c.PersonalID) 140 | else 99 end 141 | , rpt.ReportID 142 | , '5.3/5.4' 143 | from lsa_Report rpt 144 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd and n.Active = 1 145 | inner join 146 | -- HoHAdult identifies people served as heads of household or adults at any time in the report period. 147 | -- There is no corresponding column in lsa_Person -- it is only used to identify records for which 148 | -- demographic data are required / simplify the queries that set the column values. 149 | (select n.PersonalID, max(case when n.ActiveAge between 18 and 65 then 1 150 | else 0 end) 151 | --Plus ever served-as-HoH = 2 152 | + max(case when n.RelationshipToHoH <> 1 then 0 153 | else 2 end) as stat 154 | --Equals: 0=Not HoH or Adult, 1=Adult, 2=HoH, 3=Both 155 | from tlsa_Enrollment n 156 | where n.Active = 1 157 | group by n.PersonalID) HoHAdult on HoHAdult.PersonalID = n.PersonalID 158 | inner join hmis_Client c on c.PersonalID = n.PersonalID 159 | left outer join 160 | (select n.PersonalID, max(n.DisabilityStatus) as stat 161 | from tlsa_Enrollment n 162 | where n.Active = 1 163 | group by n.PersonalID) Disability on Disability.PersonalID = n.PersonalID 164 | left outer join 165 | (select n.PersonalID, min(n.DVStatus) as stat 166 | from tlsa_Enrollment n 167 | where n.Active = 1 168 | group by n.PersonalID) DV on DV.PersonalID = n.PersonalID 169 | 170 | update lp 171 | set lp.HIV = case when n.PersonalID is not null then 1 172 | when chk.PersonalID is not null then 0 173 | else -1 end 174 | from tlsa_Person lp 175 | left outer join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.ActiveAge between 18 and 65 and n.HIV = 1 176 | left outer join (select distinct n.PersonalID from tlsa_Enrollment n where n.AHAR = 1 and n.ActiveAge between 18 and 65) chk on chk.PersonalID = lp.PersonalID 177 | 178 | update lp 179 | set lp.SMI = case when n.PersonalID is not null then 1 180 | when chk.PersonalID is not null then 0 181 | else -1 end 182 | from tlsa_Person lp 183 | left outer join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.ActiveAge between 18 and 65 and n.SMI = 1 184 | left outer join (select distinct n.PersonalID from tlsa_Enrollment n where n.AHAR = 1 and n.ActiveAge between 18 and 65) chk on chk.PersonalID = lp.PersonalID 185 | 186 | update lp 187 | set lp.SUD = case when n.PersonalID is not null then 1 188 | when chk.PersonalID is not null then 0 189 | else -1 end 190 | from tlsa_Person lp 191 | left outer join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.ActiveAge between 18 and 65 and n.SUD = 1 192 | left outer join (select distinct n.PersonalID from tlsa_Enrollment n where n.AHAR = 1 and n.ActiveAge between 18 and 65) chk on chk.PersonalID = lp.PersonalID 193 | 194 | update lp 195 | set lp.DisabilityStatus = 1 196 | from tlsa_Person lp 197 | where lp.DisabilityStatus <> 1 and (lp.HIV = 1 or lp.SMI = 1 or lp.SUD = 1) 198 | 199 | /* 200 | 5.5 Get Dates for Three Year Period Relevant to Chronic Homelessness Status 201 | for Each Active Adult and Head of Household 202 | */ 203 | 204 | -- CH status is based on HMIS enrollment data in the three year period ending on the client's 205 | -- last active date in the report period. 206 | 207 | update lp 208 | set lp.LastActive = 209 | (select max(case 210 | when n.ExitDate is null and 211 | (n.LastBednight is null or n.LastBednight = rpt.ReportEnd) then rpt.ReportEnd 212 | when n.LastBednight is not null then dateadd(dd, 1, n.LastBednight) 213 | else n.ExitDate end) 214 | from lsa_Report rpt 215 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd and n.Active = 1 216 | where n.PersonalID = lp.PersonalID) 217 | , lp.Step = '5.5.1' 218 | from tlsa_Person lp 219 | where lp.HoHAdult > 0 220 | 221 | --The start of the period is: LastActive minus (3 years) plus (1 day) -- 222 | -- i.e., only people who are chronically homeless as of their most recent 223 | -- unhoused date of service will be counted as chronically homeless. 224 | update lp 225 | set lp.CHStart = dateadd(dd, 1, (dateadd(yyyy, -3, lp.LastActive))) 226 | , lp.Step = '5.5.2' 227 | from tlsa_Person lp 228 | where HoHAdult > 0 and lp.LastActive is not NULL 229 | 230 | /* 231 | 5.6 Enrollments Relevant to Counting ES/SH/Street Dates 232 | */ 233 | 234 | update n 235 | set n.CH = 1 236 | , n.Step = '5.6' 237 | from tlsa_Person lp 238 | inner join tlsa_Enrollment n on n.PersonalID = lp.PersonalID 239 | and n.EntryDate <= lp.LastActive 240 | where lp.HoHAdult > 0 241 | and (n.ExitDate is null or (n.ExitDate > lp.CHStart)) 242 | 243 | /* 244 | 5.7 Get Dates to Exclude from Counts of ES/SH/Street Days 245 | */ 246 | 247 | truncate table ch_Exclude 248 | 249 | -- ch_Exclude identifies dates between CHStart and LastActive when client was 250 | -- housed in TH (EntryDate to the day before ExitDate) and/or RRH/PSH (MoveInDate to the day before ExitDate) 251 | -- i.e., dates when the client was NOT on the street or in ES/SH based on HMIS enrollment data. 252 | -- Regardless of any potentially conflicting data, these dates will not be counted as ESSHStreetDates. 253 | insert into ch_Exclude (PersonalID, excludeDate, Step) 254 | select distinct lp.PersonalID, cal.theDate, '5.7' 255 | from tlsa_Person lp 256 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID and chn.CH = 1 257 | inner join ref_Calendar cal on cal.theDate >= 258 | case when chn.LSAProjectType in (3,13,15) then chn.MoveInDate 259 | else chn.EntryDate end 260 | and (cal.theDate < chn.ExitDate 261 | or chn.ExitDate is null) 262 | and cal.theDate between lp.CHStart and lp.LastActive 263 | where chn.LSAProjectType in (2,3,13,15) 264 | 265 | /* 266 | 5.8 Get Dates to Include in Counts of ES/SH/Street Days 267 | */ 268 | --ch_Include identifies dates on which a client was in ES/SH or on the street 269 | -- based on HMIS data (excluding any dates in ch_Exclude). 270 | 271 | truncate table ch_Include 272 | 273 | --Dates enrolled in ES entry/exit or SH (EntryDate to the day before ExitDate), 274 | -- not including any dates already accounted for in ch_Exclude 275 | insert into ch_Include (PersonalID, ESSHStreetDate, Step) 276 | select distinct lp.PersonalID, cal.theDate, '5.8.1' 277 | from tlsa_Person lp 278 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID and chn.CH = 1 279 | inner join ref_Calendar cal on 280 | cal.theDate >= chn.EntryDate 281 | and (cal.theDate < chn.ExitDate or chn.ExitDate is null) 282 | and cal.theDate between lp.CHStart and lp.LastActive 283 | left outer join ch_Exclude chx on chx.excludeDate = cal.theDate 284 | and chx.PersonalID = chn.PersonalID 285 | where chn.LSAProjectType in (0,8) 286 | and chx.excludeDate is null 287 | 288 | --ES nbn bed nights (any valid DateProvided between CHStart and LastActive 289 | -- that is not already accounted for in ch_Exclude, and not already in ch_Include) 290 | insert into ch_Include (PersonalID, ESSHStreetDate, Step) 291 | select distinct lp.PersonalID, cal.theDate, '5.8.2' 292 | from tlsa_Person lp 293 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID and chn.CH = 1 294 | inner join hmis_Services bn on bn.EnrollmentID = chn.EnrollmentID 295 | and bn.RecordType = 200 296 | and bn.DateProvided >= chn.EntryDate 297 | and (bn.DateProvided < chn.ExitDate or chn.ExitDate is null) 298 | and bn.DateDeleted is null 299 | inner join ref_Calendar cal on 300 | cal.theDate = bn.DateProvided 301 | and cal.theDate between lp.CHStart and lp.LastActive 302 | left outer join ch_Exclude chx on chx.excludeDate = cal.theDate 303 | and chx.PersonalID = chn.PersonalID 304 | left outer join ch_Include chi on chi.ESSHStreetDate = cal.theDate 305 | and chi.PersonalID = chn.PersonalID 306 | where chn.LSAProjectType = 1 and chx.excludeDate is null 307 | and chi.ESSHStreetDate is null 308 | 309 | --ES/SH/Street dates from 3.917 DateToStreetESSH when EntryDates > CHStart -- 310 | -- all dates 311 | 312 | insert into ch_Include (PersonalID, ESSHStreetDate, Step) 313 | select distinct lp.PersonalID, cal.theDate, '5.8.3' 314 | from tlsa_Person lp 315 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID 316 | and chn.EntryDate > lp.CHStart and chn.CH = 1 317 | inner join hmis_Enrollment hn on hn.EnrollmentID = chn.EnrollmentID 318 | inner join ref_Calendar cal on 319 | cal.theDate >= hn.DateToStreetESSH 320 | and cal.theDate between lp.CHStart and lp.LastActive 321 | left outer join ch_Exclude chx on chx.excludeDate = cal.theDate 322 | and chx.PersonalID = chn.PersonalID 323 | left outer join ch_Include chi on chi.ESSHStreetDate = cal.theDate 324 | and chi.PersonalID = chn.PersonalID 325 | where chx.excludeDate is null 326 | and chi.ESSHStreetDate is null 327 | and (hn.LivingSituation between 100 and 199 328 | or (chn.LSAProjectType not in (0,1,8) and hn.PreviousStreetESSH = 1 and hn.LengthOfStay in (10,11)) 329 | or (chn.LSAProjectType not in (0,1,8) and hn.PreviousStreetESSH = 1 and hn.LengthOfStay in (2,3) 330 | and hn.LivingSituation between 200 and 299) 331 | ) 332 | and ( 333 | 334 | (-- for ES/SH/TH, count dates prior to EntryDate 335 | chn.LSAProjectType in (0,1,2,8) and cal.theDate < chn.EntryDate) 336 | or (-- for PSH/RRH, dates prior to and after EntryDate are counted for 337 | -- as long as the client remains homeless in the project 338 | chn.LSAProjectType in (3,13,15) 339 | and (cal.theDate < chn.MoveInDate 340 | or (chn.MoveInDate is NULL and cal.theDate < chn.ExitDate) 341 | or (chn.MoveInDate is NULL and chn.ExitDate is NULL and cal.theDate <= lp.LastActive) 342 | ) 343 | ) 344 | ) 345 | 346 | --Gaps of less than 7 nights between two ESSHStreet dates are counted as ESSHStreetDates 347 | -- 2023: There should be no change in logic here; changes are to add comments and make the 348 | -- code more readable. 349 | insert into ch_Include (PersonalID, ESSHStreetDate, Step) 350 | select gap.PersonalID, cal.theDate, '5.8.4' 351 | from 352 | (select s.PersonalID, s.ESSHStreetDate as StartDate, min(e.ESSHStreetDate) as EndDate 353 | from ch_Include s 354 | --nogap identifies dates in ch_Include that have an ESSHStreetDate on the next day -- 355 | -- i.e., not the start of a gap -- and they are excluded in the WHERE clause 356 | left outer join ch_Include nogap on nogap.PersonalID = s.PersonalID 357 | and nogap.ESSHStreetDate = dateadd(dd, 1, s.ESSHStreetDate) 358 | -- e identifies ESSHStreetDates within 7 days after the start of a gap -- 359 | -- i.e., potential end dates for the gap -- and the earliest one is selected as EndDate 360 | inner join ch_Include e on e.PersonalID = s.PersonalID 361 | and e.ESSHStreetDate > s.ESSHStreetDate 362 | and dateadd(dd, -7, e.ESSHStreetDate) <= s.ESSHStreetDate 363 | where nogap.PersonalID is null 364 | group by s.PersonalID, s.ESSHStreetDate) gap 365 | inner join ref_Calendar cal on cal.theDate > gap.StartDate and cal.theDate < gap.EndDate 366 | 367 | /* 368 | 5.9 Get ES/SH/Street Episodes 369 | */ 370 | truncate table ch_Episodes 371 | 372 | -- For any given PersonalID: 373 | -- Any ESSHStreetDate in ch_Include without a record for the day before is the start of an episode (episodeStart). 374 | -- Any cdDate in ch_Include without a record for the day after is the end of an episode (episodeEnd). 375 | -- Each episodeStart combined with the next earliest episodeEnd represents one episode. 376 | -- The length of the episode is the difference in days between episodeStart and episodeEnd + 1 day. 377 | 378 | insert into ch_Episodes (PersonalID, episodeStart, episodeEnd, Step) 379 | select distinct s.PersonalID, s.ESSHStreetDate, min(e.ESSHStreetDate), '5.9.1' 380 | from ch_Include s 381 | inner join ch_Include e on e.PersonalID = s.PersonalID and e.ESSHStreetDate >= s.ESSHStreetDate 382 | --any date in ch_Include without a record for the day before is the start of an episode 383 | where s.PersonalID not in (select PersonalID from ch_Include where ESSHStreetDate = dateadd(dd, -1, s.ESSHStreetDate)) 384 | --any date in ch_Include without a record for the day after is the end of an episode 385 | and e.PersonalID not in (select PersonalID from ch_Include where ESSHStreetDate = dateadd(dd, 1, e.ESSHStreetDate)) 386 | group by s.PersonalID, s.ESSHStreetDate 387 | 388 | update chep 389 | set episodeDays = datediff(dd, chep.episodeStart, chep.episodeEnd) + 1 390 | , Step = '5.9.2' 391 | from ch_Episodes chep 392 | 393 | /* 394 | 5.10 Set CHTime and CHTimeStatus 395 | */ 396 | 397 | --Any client with a 365+ day episode that overlaps with their 398 | --last year of activity meets the time criteria for CH 399 | update lp 400 | set lp.CHTime = case when lp.HoHAdult = 0 then -1 else 0 end 401 | , lp.CHTimeStatus = -1 402 | , lp.Step = '5.10.1' 403 | from tlsa_Person lp 404 | 405 | update lp 406 | set CHTime = 365, CHTimeStatus = 1, lp.Step = '5.10.2' 407 | from tlsa_Person lp 408 | inner join ch_Episodes chep on chep.PersonalID = lp.PersonalID 409 | and chep.episodeDays >= 365 410 | and chep.episodeEnd > dateadd(yyyy, -1, lp.LastActive) 411 | where CHTime = 0 412 | 413 | --Clients with a total of 365+ days in the three year period and at least four episodes 414 | -- meet time criteria for CH 415 | update lp 416 | set lp.CHTime = case 417 | when ep.episodeDays >= 365 then 365 418 | when ep.episodeDays between 270 and 364 then 270 419 | else 0 end 420 | , lp.CHTimeStatus = case 421 | when ep.episodeDays < 365 then -1 422 | when ep.episodes >= 4 then 2 423 | else 3 end 424 | , lp.Step = '5.10.3' 425 | from tlsa_Person lp 426 | inner join (select chep.PersonalID 427 | , sum(chep.episodeDays) as episodeDays, count(distinct chep.episodeStart) as episodes 428 | from ch_Episodes chep 429 | group by chep.PersonalID) ep on ep.PersonalID = lp.PersonalID 430 | where lp.CHTime = 0 431 | 432 | --Clients with 3.917 data for an entry in their last year of activity 433 | -- showing 12+ months and 4+ episodes meet time criteria for CH 434 | update lp 435 | set lp.CHTime = 400 436 | , lp.CHTimeStatus = 2 437 | , lp.Step = '5.10.4' 438 | from tlsa_Person lp 439 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID and chn.CH = 1 440 | inner join hmis_Enrollment hn on hn.EnrollmentID = chn.EnrollmentID 441 | and hn.MonthsHomelessPastThreeYears in (112,113) 442 | and hn.TimesHomelessPastThreeYears = 4 443 | and chn.EntryDate > dateadd(yyyy, -1, lp.LastActive) 444 | where 445 | lp.CHTime not in (-1,365) or lp.CHTimeStatus = 3 446 | 447 | --Anyone who doesn't meet CH time criteria and is missing data in 3.917 448 | --for an active enrollment should be identified as missing data. 449 | 450 | update lp 451 | set lp.CHTimeStatus = 99 452 | , lp.Step = '5.10.5' 453 | from tlsa_Person lp 454 | inner join tlsa_Enrollment chn on chn.PersonalID = lp.PersonalID and chn.CH = 1 455 | inner join hmis_Enrollment hn on hn.EnrollmentID = chn.EnrollmentID 456 | where (lp.CHTime in (0,270) or lp.CHTimeStatus = 3) 457 | and (hn.DateToStreetESSH > chn.EntryDate 458 | or (hn.LivingSituation < 100 or hn.LivingSituation is null) 459 | or (hn.LengthOfStay in (8,9,99) or hn.LengthOfStay is null) 460 | or (chn.LSAProjectType not in (0,1,8) and hn.LivingSituation between 200 and 299 461 | and hn.LengthOfStay in (2,3) 462 | and (hn.PreviousStreetESSH is null or hn.PreviousStreetESSH not in (0,1))) 463 | or (chn.LSAProjectType not in (0,1,8) and hn.LengthOfStay in (10,11) 464 | and (hn.PreviousStreetESSH is null or hn.PreviousStreetESSH not in (0,1))) 465 | or ((chn.LSAProjectType in (0,1,8) 466 | or hn.LivingSituation between 100 and 199 467 | or (chn.LSAProjectType not in (0,1,8) and hn.LivingSituation between 200 and 299 468 | and hn.LengthOfStay in (2,3) 469 | and hn.PreviousStreetESSH = 1) 470 | or (chn.LSAProjectType not in (0,1,8) and hn.LengthOfStay in (10,11) 471 | and hn.PreviousStreetESSH = 1) 472 | ) 473 | and ( 474 | hn.MonthsHomelessPastThreeYears in (8,9,99) 475 | or hn.MonthsHomelessPastThreeYears is null 476 | or hn.TimesHomelessPastThreeYears in (8,9,99) 477 | or hn.TimesHomelessPastThreeYears is null 478 | or hn.DateToStreetESSH is null 479 | ) 480 | )) 481 | 482 | /* 483 | 5.11 EST/RRH/PSH/RRHSO AgeMin and AgeMax - LSAPerson 484 | */ 485 | 486 | update lp 487 | set ESTAgeMin = coalesce( 488 | (select min(n.ActiveAge) 489 | from tlsa_Enrollment n 490 | where n.PersonalID = lp.PersonalID and n.LSAProjectType in (0,1,2,8) and n.Active = 1) 491 | , -1) 492 | , lp.Step = '5.11.1' 493 | from tlsa_Person lp 494 | 495 | update lp 496 | set ESTAgeMax = coalesce( 497 | (select max(n.ActiveAge) 498 | from tlsa_Enrollment n 499 | where n.PersonalID = lp.PersonalID and n.LSAProjectType in (0,1,2,8) and n.Active = 1) 500 | , -1) 501 | , lp.Step = '5.11.2' 502 | from tlsa_Person lp 503 | 504 | update lp 505 | set RRHAgeMin = coalesce( 506 | (select min(n.ActiveAge) 507 | from tlsa_Enrollment n 508 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 13 and n.Active = 1) 509 | , -1) 510 | , lp.Step = '5.11.3' 511 | from tlsa_Person lp 512 | 513 | update lp 514 | set RRHAgeMax = coalesce( 515 | (select max(n.ActiveAge) 516 | from tlsa_Enrollment n 517 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 13 and n.Active = 1) 518 | , -1) 519 | , lp.Step = '5.11.4' 520 | from tlsa_Person lp 521 | 522 | update lp 523 | set PSHAgeMin = coalesce( 524 | (select min(n.ActiveAge) 525 | from tlsa_Enrollment n 526 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 3 and n.Active = 1) 527 | , -1) 528 | , lp.Step = '5.11.5' 529 | from tlsa_Person lp 530 | 531 | update lp 532 | set PSHAgeMax = coalesce( 533 | (select max(n.ActiveAge) 534 | from tlsa_Enrollment n 535 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 3 and n.Active = 1) 536 | , -1) 537 | , lp.Step = '5.11.6' 538 | from tlsa_Person lp 539 | 540 | update lp 541 | set RRHSOAgeMin = coalesce( 542 | (select min(n.ActiveAge) 543 | from tlsa_Enrollment n 544 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 15 and n.Active = 1) 545 | , -1) 546 | , lp.Step = '5.11.3' 547 | from tlsa_Person lp 548 | 549 | update lp 550 | set RRHSOAgeMax = coalesce( 551 | (select max(n.ActiveAge) 552 | from tlsa_Enrollment n 553 | where n.PersonalID = lp.PersonalID and n.LSAProjectType = 15 and n.Active = 1) 554 | , -1) 555 | , lp.Step = '5.11.4' 556 | from tlsa_Person lp 557 | 558 | 559 | -------------------------------------------------------------------------------- /05_12 to 05_15 LSAPerson Project Group and Population Household Types.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 05_12 to 05_15 LSAPerson Project Group and Population Household Types.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode 10 | 11 | 5.12 Set Population Identifiers for Active HouseholdIDs 12 | */ 13 | 14 | update hhid 15 | set hhid.HHChronic = coalesce((select min( 16 | case when ((lp.CHTime = 365 and lp.CHTimeStatus in (1,2)) 17 | or (lp.CHTime = 400 and lp.CHTimeStatus = 2)) 18 | and lp.DisabilityStatus = 1 then 1 19 | when lp.CHTime in (365, 400) and lp.DisabilityStatus = 1 then 2 20 | when lp.CHTime in (365, 400) and lp.DisabilityStatus = 99 then 3 21 | when lp.CHTime in (365, 400) and lp.DisabilityStatus = 0 then 4 22 | when lp.CHTime = 270 and lp.DisabilityStatus = 1 and lp.CHTimeStatus = 99 then 5 23 | when lp.CHTime = 270 and lp.DisabilityStatus = 1 and lp.CHTimeStatus <> 99 then 6 24 | when lp.CHTimeStatus = 99 and lp.DisabilityStatus <> 0 then 9 25 | else null end) 26 | from tlsa_Person lp 27 | inner join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.Active = 1 28 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 29 | inner join tlsa_HHID hh on hh.HouseholdID = n.HouseholdID 30 | where n.HouseholdID = hhid.HouseholdID), 0) 31 | , hhid.HHVet = coalesce((select max( 32 | case when lp.VetStatus = 1 33 | and n.ActiveAge between 18 and 65 34 | and hh.ActiveHHType <> 3 then 1 35 | else 0 end) 36 | from tlsa_Person lp 37 | inner join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.Active = 1 38 | inner join tlsa_HHID hh on hh.HouseholdID = n.HouseholdID 39 | where n.HouseholdID = hhid.HouseholdID), 0) 40 | , hhid.HHDisability = coalesce((select max( 41 | case when lp.DisabilityStatus = 1 42 | and (n.ActiveAge between 18 and 65 or n.RelationshipToHoH = 1) then 1 43 | else 0 end) 44 | from tlsa_Person lp 45 | inner join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.Active = 1 46 | where n.HouseholdID = hhid.HouseholdID), 0) 47 | , hhid.HHFleeingDV = coalesce((select min( 48 | case when lp.DVStatus = 1 49 | and (n.ActiveAge between 18 and 65 or n.RelationshipToHoH = 1) then 1 50 | when lp.DVStatus in (2,3) 51 | and (n.ActiveAge between 18 and 65 or n.RelationshipToHoH = 1) then 2 52 | else null end) 53 | from tlsa_Person lp 54 | inner join tlsa_Enrollment n on n.PersonalID = lp.PersonalID and n.Active = 1 55 | where n.HouseholdID = hhid.HouseholdID), 0) 56 | --Set HHAdultAge for active households based on HH member AgeGroup(s) 57 | , hhid.HHAdultAge = (select 58 | -- n/a except for AO and AC households 59 | case when hhid.ActiveHHType not in (1,2) then -1 60 | -- n/a for AC households with members of unknown age 61 | when max(n.ActiveAge) >= 98 then -1 62 | -- 18-21 63 | when max(n.ActiveAge) = 21 then 18 64 | -- 22-24 65 | when max(n.ActiveAge) = 24 then 24 66 | -- 55+ 67 | when min(n.ActiveAge) between 64 and 65 then 55 68 | -- all other combinations 69 | else 25 end 70 | from tlsa_Enrollment n 71 | where n.HouseholdID = hhid.HouseholdID and n.Active = 1) 72 | , hhid.AC3Plus = (select case sum(case when n.ActiveAge <= 17 and hh.ActiveHHType = 2 then 1 73 | else 0 end) 74 | when 0 then 0 75 | when 1 then 0 76 | when 2 then 0 77 | else 1 end 78 | from tlsa_Enrollment n 79 | inner join tlsa_HHID hh on hh.HouseholdID = n.HouseholdID 80 | where n.Active = 1 and n.HouseholdID = hhid.HouseholdID) 81 | , hhid.Step = '5.12.1' 82 | from tlsa_HHID hhid 83 | where hhid.Active = 1 84 | 85 | update hhid 86 | set hhid.HHParent = coalesce((select max( 87 | case when n.RelationshipToHoH = 2 then 1 88 | else 0 end) 89 | from tlsa_Enrollment n 90 | where n.Active = 1 and n.HouseholdID = hhid.HouseholdID), 0) 91 | , hhid.Step = '5.12.2' 92 | from tlsa_HHID hhid 93 | where hhid.Active = 1 94 | 95 | 96 | /* 97 | 5.13 Set tlsa_Person Project Group and Population Household Types 98 | */ 99 | 100 | 101 | update lp 102 | set lp.HHTypeEST = (select sum(distinct case hhid.ActiveHHType 103 | when 1 then 1000 104 | when 2 then 200 105 | when 3 then 30 106 | else 9 end) 107 | from tlsa_Enrollment n 108 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 109 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8)) 110 | , lp.HoHEST = (select sum(distinct case hhid.ActiveHHType 111 | when 1 then 1000 112 | when 2 then 200 113 | when 3 then 30 114 | else 9 end) 115 | from tlsa_Enrollment n 116 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 117 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 118 | and n.RelationshipToHoH = 1) 119 | , lp.AdultEST = (select sum(distinct case hhid.ActiveHHType 120 | when 1 then 1000 121 | when 2 then 200 122 | when 3 then 30 123 | else 9 end) 124 | from tlsa_Enrollment n 125 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 126 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 127 | and n.ActiveAge between 18 and 65) 128 | , lp.AHAREST = (select sum(distinct case hhid.ActiveHHType 129 | when 1 then 1000 130 | when 2 then 200 131 | when 3 then 30 132 | else 9 end) 133 | from tlsa_Enrollment n 134 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 135 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType in (0,1,2,8)) 136 | , lp.AHARHoHEST = (select sum(distinct case hhid.ActiveHHType 137 | when 1 then 1000 138 | when 2 then 200 139 | when 3 then 30 140 | else 9 end) 141 | from tlsa_Enrollment n 142 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 143 | where n.PersonalID = lp.PersonalID and n.AHAR= 1 and n.LSAProjectType in (0,1,2,8) 144 | and n.RelationshipToHoH = 1) 145 | , lp.AHARAdultEST = (select sum(distinct case hhid.ActiveHHType 146 | when 1 then 1000 147 | when 2 then 200 148 | when 3 then 30 149 | else 9 end) 150 | from tlsa_Enrollment n 151 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 152 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType in (0,1,2,8) 153 | and n.ActiveAge between 18 and 65) 154 | , lp.HHChronicEST = (select sum(distinct case hhid.ActiveHHType 155 | when 1 then 1000 156 | when 2 then 200 157 | when 3 then 30 158 | else 9 end) 159 | from tlsa_Enrollment n 160 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 161 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 162 | and hhid.HHChronic = 1) 163 | , lp.HHVetEST = (select sum(distinct case hhid.ActiveHHType 164 | when 1 then 1000 165 | when 2 then 200 166 | when 3 then 30 167 | else 9 end) 168 | from tlsa_Enrollment n 169 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 170 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 171 | and hhid.HHVet = 1) 172 | , lp.HHDisabilityEST = (select sum(distinct case hhid.ActiveHHType 173 | when 1 then 1000 174 | when 2 then 200 175 | when 3 then 30 176 | else 9 end) 177 | from tlsa_Enrollment n 178 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 179 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 180 | and hhid.HHDisability = 1) 181 | , lp.HHFleeingDVEST = (select sum(distinct case hhid.ActiveHHType 182 | when 1 then 1000 183 | when 2 then 200 184 | when 3 then 30 185 | else 9 end) 186 | from tlsa_Enrollment n 187 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 188 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 189 | and hhid.HHFleeingDV = 1) 190 | , lp.HHParentEST = (select sum(distinct case hhid.ActiveHHType 191 | when 1 then 1000 192 | when 2 then 200 193 | when 3 then 30 194 | else 9 end) 195 | from tlsa_Enrollment n 196 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 197 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8) 198 | and hhid.HHParent = 1) 199 | , lp.AC3PlusEST = (select sum(distinct case when hhid.AC3Plus = 1 then 1 else 0 end) 200 | from tlsa_Enrollment n 201 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 202 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1,2,8)) 203 | , lp.HHTypeRRH = (select sum(distinct case hhid.ActiveHHType 204 | when 1 then 1000 205 | when 2 then 200 206 | when 3 then 30 207 | else 9 end) 208 | from tlsa_Enrollment n 209 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 210 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13) 211 | , lp.HoHRRH = (select sum(distinct case hhid.ActiveHHType 212 | when 1 then 1000 213 | when 2 then 200 214 | when 3 then 30 215 | else 9 end) 216 | from tlsa_Enrollment n 217 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 218 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 219 | and n.RelationshipToHoH = 1) 220 | , lp.AdultRRH = (select sum(distinct case hhid.ActiveHHType 221 | when 1 then 1000 222 | when 2 then 200 223 | when 3 then 30 224 | else 9 end) 225 | from tlsa_Enrollment n 226 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 227 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 228 | and n.ActiveAge between 18 and 65) 229 | , lp.AHARRRH = (select sum(distinct case hhid.ActiveHHType 230 | when 1 then 1000 231 | when 2 then 200 232 | when 3 then 30 233 | else 9 end) 234 | from tlsa_Enrollment n 235 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 236 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 13) 237 | , lp.AHARHoHRRH = (select sum(distinct case hhid.ActiveHHType 238 | when 1 then 1000 239 | when 2 then 200 240 | when 3 then 30 241 | else 9 end) 242 | from tlsa_Enrollment n 243 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 244 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 13 245 | and n.RelationshipToHoH = 1) 246 | , lp.AHARAdultRRH = (select sum(distinct case hhid.ActiveHHType 247 | when 1 then 1000 248 | when 2 then 200 249 | when 3 then 30 250 | else 9 end) 251 | from tlsa_Enrollment n 252 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 253 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 13 254 | and n.ActiveAge between 18 and 65) 255 | , lp.HHChronicRRH = (select sum(distinct case hhid.ActiveHHType 256 | when 1 then 1000 257 | when 2 then 200 258 | when 3 then 30 259 | else 9 end) 260 | from tlsa_Enrollment n 261 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 262 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 263 | and hhid.HHChronic = 1) 264 | , lp.HHVetRRH = (select sum(distinct case hhid.ActiveHHType 265 | when 1 then 1000 266 | when 2 then 200 267 | when 3 then 30 268 | else 9 end) 269 | from tlsa_Enrollment n 270 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 271 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 272 | and hhid.HHVet = 1) 273 | , lp.HHDisabilityRRH = (select sum(distinct case hhid.ActiveHHType 274 | when 1 then 1000 275 | when 2 then 200 276 | when 3 then 30 277 | else 9 end) 278 | from tlsa_Enrollment n 279 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 280 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 281 | and hhid.HHDisability = 1) 282 | , lp.HHFleeingDVRRH = (select sum(distinct case hhid.ActiveHHType 283 | when 1 then 1000 284 | when 2 then 200 285 | when 3 then 30 286 | else 9 end) 287 | from tlsa_Enrollment n 288 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 289 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 290 | and hhid.HHFleeingDV = 1) 291 | , lp.HHParentRRH = (select sum(distinct case hhid.ActiveHHType 292 | when 1 then 1000 293 | when 2 then 200 294 | when 3 then 30 295 | else 9 end) 296 | from tlsa_Enrollment n 297 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 298 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13 299 | and hhid.HHParent = 1) 300 | , lp.AC3PlusRRH = (select sum(distinct case when hhid.AC3Plus = 1 then 1 else 0 end) 301 | from tlsa_Enrollment n 302 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 303 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 13) 304 | , lp.HHTypePSH = (select sum(distinct case hhid.ActiveHHType 305 | when 1 then 1000 306 | when 2 then 200 307 | when 3 then 30 308 | else 9 end) 309 | from tlsa_Enrollment n 310 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 311 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3) 312 | , lp.HoHPSH = (select sum(distinct case hhid.ActiveHHType 313 | when 1 then 1000 314 | when 2 then 200 315 | when 3 then 30 316 | else 9 end) 317 | from tlsa_Enrollment n 318 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 319 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 320 | and n.RelationshipToHoH = 1) 321 | , lp.AdultPSH = (select sum(distinct case hhid.ActiveHHType 322 | when 1 then 1000 323 | when 2 then 200 324 | when 3 then 30 325 | else 9 end) 326 | from tlsa_Enrollment n 327 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 328 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 329 | and n.ActiveAge between 18 and 65) 330 | , lp.AHARPSH = (select sum(distinct case hhid.ActiveHHType 331 | when 1 then 1000 332 | when 2 then 200 333 | when 3 then 30 334 | else 9 end) 335 | from tlsa_Enrollment n 336 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 337 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 3) 338 | , lp.AHARHoHPSH = (select sum(distinct case hhid.ActiveHHType 339 | when 1 then 1000 340 | when 2 then 200 341 | when 3 then 30 342 | else 9 end) 343 | from tlsa_Enrollment n 344 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 345 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 3 346 | and n.RelationshipToHoH = 1) 347 | , lp.AHARAdultPSH = (select sum(distinct case hhid.ActiveHHType 348 | when 1 then 1000 349 | when 2 then 200 350 | when 3 then 30 351 | else 9 end) 352 | from tlsa_Enrollment n 353 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 354 | where n.PersonalID = lp.PersonalID and n.AHAR = 1 and n.LSAProjectType = 3 355 | and n.ActiveAge between 18 and 65) 356 | , lp.HHChronicPSH = (select sum(distinct case hhid.ActiveHHType 357 | when 1 then 1000 358 | when 2 then 200 359 | when 3 then 30 360 | else 9 end) 361 | from tlsa_Enrollment n 362 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 363 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 364 | and hhid.HHChronic = 1) 365 | , lp.HHVetPSH = (select sum(distinct case hhid.ActiveHHType 366 | when 1 then 1000 367 | when 2 then 200 368 | when 3 then 30 369 | else 9 end) 370 | from tlsa_Enrollment n 371 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 372 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 373 | and hhid.HHVet = 1) 374 | , lp.HHDisabilityPSH = (select sum(distinct case hhid.ActiveHHType 375 | when 1 then 1000 376 | when 2 then 200 377 | when 3 then 30 378 | else 9 end) 379 | from tlsa_Enrollment n 380 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 381 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 382 | and hhid.HHDisability = 1) 383 | , lp.HHFleeingDVPSH = (select sum(distinct case hhid.ActiveHHType 384 | when 1 then 1000 385 | when 2 then 200 386 | when 3 then 30 387 | else 9 end) 388 | from tlsa_Enrollment n 389 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 390 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 391 | and hhid.HHFleeingDV = 1) 392 | , lp.HHParentPSH = (select sum(distinct case hhid.ActiveHHType 393 | when 1 then 1000 394 | when 2 then 200 395 | when 3 then 30 396 | else 9 end) 397 | from tlsa_Enrollment n 398 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 399 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3 400 | and hhid.HHParent = 1) 401 | , lp.AC3PlusPSH = (select sum(distinct case when hhid.AC3Plus = 1 then 1 else 0 end) 402 | from tlsa_Enrollment n 403 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 404 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 3) 405 | , lp.HHTypeRRHSONoMI = (select sum(distinct case hhid.ActiveHHType 406 | when 1 then 1000 407 | when 2 then 200 408 | when 3 then 30 409 | else 9 end) 410 | from tlsa_Enrollment n 411 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 412 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.MoveInDate is null and n.LSAProjectType = 15) 413 | , lp.HHTypeRRHSOMI = (select sum(distinct case hhid.ActiveHHType 414 | when 1 then 1000 415 | when 2 then 200 416 | when 3 then 30 417 | else 9 end) 418 | from tlsa_Enrollment n 419 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 420 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.MoveInDate is not null and n.LSAProjectType = 15) 421 | , lp.HHTypeES = (select sum(distinct case hhid.ActiveHHType 422 | when 1 then 1000 423 | when 2 then 200 424 | when 3 then 30 425 | else 9 end) 426 | from tlsa_Enrollment n 427 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 428 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType in (0,1)) 429 | , lp.HHTypeSH = (select sum(distinct case hhid.ActiveHHType 430 | when 1 then 1000 431 | when 2 then 200 432 | when 3 then 30 433 | else 9 end) 434 | from tlsa_Enrollment n 435 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 436 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 8) 437 | , lp.HHTypeTH = (select sum(distinct case hhid.ActiveHHType 438 | when 1 then 1000 439 | when 2 then 200 440 | when 3 then 30 441 | else 9 end) 442 | from tlsa_Enrollment n 443 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 444 | where n.PersonalID = lp.PersonalID and n.Active = 1 and n.LSAProjectType = 2) 445 | , lp.Step = '5.13.1' 446 | from tlsa_Person lp 447 | 448 | update lp 449 | set lp.AC3PlusEST = case when lp.AC3PlusEST is NULL then -1 else cast(replace(cast(lp.AC3PlusEST as varchar), '0', '') as int) end 450 | , lp.AC3PlusPSH = case when lp.AC3PlusPSH is NULL then -1 else cast(replace(cast(lp.AC3PlusPSH as varchar), '0', '') as int) end 451 | , lp.AC3PlusRRH = case when lp.AC3PlusRRH is NULL then -1 else cast(replace(cast(lp.AC3PlusRRH as varchar), '0', '') as int) end 452 | , lp.AdultEST = case when lp.AdultEST is NULL then -1 else cast(replace(cast(lp.AdultEST as varchar), '0', '') as int) end 453 | , lp.AdultPSH = case when lp.AdultPSH is NULL then -1 else cast(replace(cast(lp.AdultPSH as varchar), '0', '') as int) end 454 | , lp.AdultRRH = case when lp.AdultRRH is NULL then -1 else cast(replace(cast(lp.AdultRRH as varchar), '0', '') as int) end 455 | , lp.AHARAdultEST = case when lp.AHARAdultEST is NULL then -1 else cast(replace(cast(lp.AHARAdultEST as varchar), '0', '') as int) end 456 | , lp.AHARAdultPSH = case when lp.AHARAdultPSH is NULL then -1 else cast(replace(cast(lp.AHARAdultPSH as varchar), '0', '') as int) end 457 | , lp.AHARAdultRRH = case when lp.AHARAdultRRH is NULL then -1 else cast(replace(cast(lp.AHARAdultRRH as varchar), '0', '') as int) end 458 | , lp.AHAREST = case when lp.AHAREST is NULL then -1 else cast(replace(cast(lp.AHAREST as varchar), '0', '') as int) end 459 | , lp.AHARHoHEST = case when lp.AHARHoHEST is NULL then -1 else cast(replace(cast(lp.AHARHoHEST as varchar), '0', '') as int) end 460 | , lp.AHARHoHPSH = case when lp.AHARHoHPSH is NULL then -1 else cast(replace(cast(lp.AHARHoHPSH as varchar), '0', '') as int) end 461 | , lp.AHARHoHRRH = case when lp.AHARHoHRRH is NULL then -1 else cast(replace(cast(lp.AHARHoHRRH as varchar), '0', '') as int) end 462 | , lp.AHARPSH = case when lp.AHARPSH is NULL then -1 else cast(replace(cast(lp.AHARPSH as varchar), '0', '') as int) end 463 | , lp.AHARRRH = case when lp.AHARRRH is NULL then -1 else cast(replace(cast(lp.AHARRRH as varchar), '0', '') as int) end 464 | , lp.HHChronicEST = case when lp.HHChronicEST is NULL then -1 else cast(replace(cast(lp.HHChronicEST as varchar), '0', '') as int) end 465 | , lp.HHChronicPSH = case when lp.HHChronicPSH is NULL then -1 else cast(replace(cast(lp.HHChronicPSH as varchar), '0', '') as int) end 466 | , lp.HHChronicRRH = case when lp.HHChronicRRH is NULL then -1 else cast(replace(cast(lp.HHChronicRRH as varchar), '0', '') as int) end 467 | , lp.HHDisabilityEST = case when lp.HHDisabilityEST is NULL then -1 else cast(replace(cast(lp.HHDisabilityEST as varchar), '0', '') as int) end 468 | , lp.HHDisabilityPSH = case when lp.HHDisabilityPSH is NULL then -1 else cast(replace(cast(lp.HHDisabilityPSH as varchar), '0', '') as int) end 469 | , lp.HHDisabilityRRH = case when lp.HHDisabilityRRH is NULL then -1 else cast(replace(cast(lp.HHDisabilityRRH as varchar), '0', '') as int) end 470 | , lp.HHFleeingDVEST = case when lp.HHFleeingDVEST is NULL then -1 else cast(replace(cast(lp.HHFleeingDVEST as varchar), '0', '') as int) end 471 | , lp.HHFleeingDVPSH = case when lp.HHFleeingDVPSH is NULL then -1 else cast(replace(cast(lp.HHFleeingDVPSH as varchar), '0', '') as int) end 472 | , lp.HHFleeingDVRRH = case when lp.HHFleeingDVRRH is NULL then -1 else cast(replace(cast(lp.HHFleeingDVRRH as varchar), '0', '') as int) end 473 | , lp.HHParentEST = case when lp.HHParentEST is NULL then -1 else cast(replace(cast(lp.HHParentEST as varchar), '0', '') as int) end 474 | , lp.HHParentPSH = case when lp.HHParentPSH is NULL then -1 else cast(replace(cast(lp.HHParentPSH as varchar), '0', '') as int) end 475 | , lp.HHParentRRH = case when lp.HHParentRRH is NULL then -1 else cast(replace(cast(lp.HHParentRRH as varchar), '0', '') as int) end 476 | , lp.HHTypeEST = case when lp.HHTypeEST is NULL then -1 else cast(replace(cast(lp.HHTypeEST as varchar), '0', '') as int) end 477 | , lp.HHTypePSH = case when lp.HHTypePSH is NULL then -1 else cast(replace(cast(lp.HHTypePSH as varchar), '0', '') as int) end 478 | , lp.HHTypeRRH = case when lp.HHTypeRRH is NULL then -1 else cast(replace(cast(lp.HHTypeRRH as varchar), '0', '') as int) end 479 | , lp.HHVetEST = case when lp.HHVetEST is NULL then -1 else cast(replace(cast(lp.HHVetEST as varchar), '0', '') as int) end 480 | , lp.HHVetPSH = case when lp.HHVetPSH is NULL then -1 else cast(replace(cast(lp.HHVetPSH as varchar), '0', '') as int) end 481 | , lp.HHVetRRH = case when lp.HHVetRRH is NULL then -1 else cast(replace(cast(lp.HHVetRRH as varchar), '0', '') as int) end 482 | , lp.HoHEST = case when lp.HoHEST is NULL then -1 else cast(replace(cast(lp.HoHEST as varchar), '0', '') as int) end 483 | , lp.HoHPSH = case when lp.HoHPSH is NULL then -1 else cast(replace(cast(lp.HoHPSH as varchar), '0', '') as int) end 484 | , lp.HoHRRH = case when lp.HoHRRH is NULL then -1 else cast(replace(cast(lp.HoHRRH as varchar), '0', '') as int) end 485 | , lp.HHTypeES = case when lp.HHTypeES is NULL then -1 else cast(replace(cast(lp.HHTypeES as varchar), '0', '') as int) end 486 | , lp.HHTypeSH = case when lp.HHTypeSH is NULL then -1 else cast(replace(cast(lp.HHTypeSH as varchar), '0', '') as int) end 487 | , lp.HHTypeTH = case when lp.HHTypeTH is NULL then -1 else cast(replace(cast(lp.HHTypeTH as varchar), '0', '') as int) end 488 | , lp.PSHAgeMax = case when lp.PSHAgeMax is NULL then -1 else lp.PSHAgeMax end 489 | , lp.PSHAgeMin = case when lp.PSHAgeMin is NULL then -1 else lp.PSHAgeMin end 490 | , lp.RRHAgeMax = case when lp.RRHAgeMax is NULL then -1 else lp.RRHAgeMax end 491 | , lp.RRHAgeMin = case when lp.RRHAgeMin is NULL then -1 else lp.RRHAgeMin end 492 | , lp.ESTAgeMax = case when lp.ESTAgeMax is NULL then -1 else lp.ESTAgeMax end 493 | , lp.ESTAgeMin = case when lp.ESTAgeMin is NULL then -1 else lp.ESTAgeMin end 494 | , lp.RRHSOAgeMin = case when lp.RRHSOAgeMin is NULL then -1 else lp.RRHSOAgeMin end 495 | , lp.RRHSOAgeMax = case when lp.RRHSOAgeMax is NULL then -1 else lp.RRHSOAgeMax end 496 | , lp.HHTypeRRHSONoMI = case when lp.HHTypeRRHSONoMI is NULL then -1 else cast(replace(cast(lp.HHTypeRRHSONoMI as varchar), '0', '') as int) end 497 | , lp.HHTypeRRHSOMI = case when lp.HHTypeRRHSOMI is NULL then -1 else cast(replace(cast(lp.HHTypeRRHSOMI as varchar), '0', '') as int) end 498 | , Step = '5.13.2' 499 | from tlsa_Person lp 500 | 501 | /* 502 | 5.14 Adult Age Population Identifiers - LSAPerson 503 | */ 504 | update lp 505 | set lp.HHAdultAgeAOEST = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 506 | then min(hhid.HHAdultAge) 507 | else max(hhid.HHAdultAge) end 508 | from tlsa_Enrollment n 509 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 510 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 1 511 | and hhid.LSAProjectType in (0,1,2,8) 512 | where n.PersonalID = lp.PersonalID and n.Active = 1), -1) 513 | , lp.HHAdultAgeACEST = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 514 | then min(hhid.HHAdultAge) 515 | else max(hhid.HHAdultAge) end 516 | from tlsa_Enrollment n 517 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 518 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 2 519 | and hhid.LSAProjectType in (0,1,2,8) 520 | where n.PersonalID = lp.PersonalID and n.Active = 1), -1) 521 | , lp.HHAdultAgeAORRH = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 522 | then min(hhid.HHAdultAge) 523 | else max(hhid.HHAdultAge) end 524 | from tlsa_Enrollment n 525 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 526 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 1 527 | and hhid.LSAProjectType = 13 528 | where n.PersonalID = lp.PersonalID and n.Active = 1), -1) 529 | , lp.HHAdultAgeACRRH = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 530 | then min(hhid.HHAdultAge) 531 | else max(hhid.HHAdultAge) end 532 | from tlsa_Enrollment n 533 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 534 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 2 535 | and hhid.LSAProjectType = 13 536 | where n.PersonalID = lp.PersonalID 537 | and n.Active = 1), -1) 538 | , lp.HHAdultAgeAOPSH = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 539 | then min(hhid.HHAdultAge) 540 | else max(hhid.HHAdultAge) end 541 | from tlsa_Enrollment n 542 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 543 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 1 544 | and hhid.LSAProjectType = 3 545 | where n.PersonalID = lp.PersonalID and n.Active = 1), -1) 546 | , lp.HHAdultAgeACPSH = coalesce((select case when min(hhid.HHAdultAge) between 18 and 24 547 | then min(hhid.HHAdultAge) 548 | else max(hhid.HHAdultAge) end 549 | from tlsa_Enrollment n 550 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 551 | and hhid.HHAdultAge between 18 and 55 and hhid.ActiveHHType = 2 552 | and hhid.LSAProjectType = 3 553 | where n.PersonalID = lp.PersonalID and n.Active = 1), -1) 554 | , lp.Step = '5.14' 555 | from tlsa_Person lp 556 | 557 | /* 558 | 5.15 Select Data for Export to LSAPerson 559 | */ 560 | -- LSAPerson 561 | delete from lsa_Person 562 | insert into lsa_Person (RowTotal 563 | , Gender, RaceEthnicity, VetStatus, DisabilityStatus 564 | , CHTime, CHTimeStatus, DVStatus 565 | , ESTAgeMin, ESTAgeMax, HHTypeEST, HoHEST, AdultEST, AHARAdultEST, HHChronicEST, HHVetEST, HHDisabilityEST 566 | , HHFleeingDVEST, HHAdultAgeAOEST, HHAdultAgeACEST, HHParentEST, AC3PlusEST, AHAREST, AHARHoHEST 567 | , RRHAgeMin, RRHAgeMax, HHTypeRRH, HoHRRH, AdultRRH, AHARAdultRRH, HHChronicRRH, HHVetRRH, HHDisabilityRRH 568 | , HHFleeingDVRRH, HHAdultAgeAORRH, HHAdultAgeACRRH, HHParentRRH, AC3PlusRRH, AHARRRH, AHARHoHRRH 569 | , PSHAgeMin, PSHAgeMax, HHTypePSH, HoHPSH, AdultPSH, AHARAdultPSH, HHChronicPSH, HHVetPSH, HHDisabilityPSH 570 | , HHFleeingDVPSH, HHAdultAgeAOPSH, HHAdultAgeACPSH, HHParentPSH, AC3PlusPSH, AHARPSH, AHARHoHPSH 571 | , RRHSOAgeMin, RRHSOAgeMax, HHTypeRRHSONoMI, HHTypeRRHSOMI 572 | , HHTypeES, HHTypeSH, HHTypeTH, HIV, SMI, SUD 573 | , ReportID 574 | ) 575 | select count(distinct PersonalID) 576 | , Gender, RaceEthnicity, VetStatus, DisabilityStatus 577 | , CHTime, CHTimeStatus, DVStatus 578 | , ESTAgeMin, ESTAgeMax, HHTypeEST, HoHEST, AdultEST, AHARAdultEST, HHChronicEST, HHVetEST, HHDisabilityEST 579 | , HHFleeingDVEST, HHAdultAgeAOEST, HHAdultAgeACEST, HHParentEST, AC3PlusEST, AHAREST, AHARHoHEST 580 | , RRHAgeMin, RRHAgeMax, HHTypeRRH, HoHRRH, AdultRRH, AHARAdultRRH, HHChronicRRH, HHVetRRH, HHDisabilityRRH 581 | , HHFleeingDVRRH, HHAdultAgeAORRH, HHAdultAgeACRRH, HHParentRRH, AC3PlusRRH, AHARRRH, AHARHoHRRH 582 | , PSHAgeMin, PSHAgeMax, HHTypePSH, HoHPSH, AdultPSH, AHARAdultPSH, HHChronicPSH, HHVetPSH, HHDisabilityPSH 583 | , HHFleeingDVPSH, HHAdultAgeAOPSH, HHAdultAgeACPSH, HHParentPSH, AC3PlusPSH, AHARPSH, AHARHoHPSH 584 | , RRHSOAgeMin, RRHSOAgeMax, HHTypeRRHSONoMI, HHTypeRRHSOMI 585 | , HHTypeES, HHTypeSH, HHTypeTH, HIV, SMI, SUD 586 | , ReportID 587 | from tlsa_Person 588 | group by 589 | Gender, RaceEthnicity, VetStatus, DisabilityStatus 590 | , CHTime, CHTimeStatus, DVStatus 591 | , ESTAgeMin, ESTAgeMax, HHTypeEST, HoHEST, AdultEST, AHARAdultEST, HHChronicEST, HHVetEST, HHDisabilityEST 592 | , HHFleeingDVEST, HHAdultAgeAOEST, HHAdultAgeACEST, HHParentEST, AC3PlusEST, AHAREST, AHARHoHEST 593 | , RRHAgeMin, RRHAgeMax, HHTypeRRH, HoHRRH, AdultRRH, AHARAdultRRH, HHChronicRRH, HHVetRRH, HHDisabilityRRH 594 | , HHFleeingDVRRH, HHAdultAgeAORRH, HHAdultAgeACRRH, HHParentRRH, AC3PlusRRH, AHARRRH, AHARHoHRRH 595 | , PSHAgeMin, PSHAgeMax, HHTypePSH, HoHPSH, AdultPSH, AHARAdultPSH, HHChronicPSH, HHVetPSH, HHDisabilityPSH 596 | , HHFleeingDVPSH, HHAdultAgeAOPSH, HHAdultAgeACPSH, HHParentPSH, AC3PlusPSH, AHARPSH, AHARHoHPSH 597 | , RRHSOAgeMin, RRHSOAgeMax, HHTypeRRHSONoMI, HHTypeRRHSOMI 598 | , HHTypeES, HHTypeSH, HHTypeTH, HIV, SMI, SUD 599 | , ReportID 600 | 601 | /* 602 | End LSAPerson 603 | */ 604 | -------------------------------------------------------------------------------- /08 LSACalculated Averages for LSAHousehold and LSAExit.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 08 LSACalculated Averages for LSAHousehold and LSAExit.sql 4 | 5 | FY2024 Changes 6 | 7 | Run code only if the LSAScope is not 'HIC' 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode)/ 10 | 11 | Uses static reference tables: 12 | ref_RowValues - Required Cohort, Universe, SystemPath values for each RowID 13 | ref_RowPopulations - Required Populations for each RowID 14 | and (for rows 1-9) whether the RowID is required by SystemPath for the Population 15 | ref_PopHHTypes - HHTypes required in LSACalculated for each Population by PopID 16 | 17 | Populates and references: 18 | tlsa_AveragePops - By PopID -- HoHID, HHType, and Cohort for each population member 19 | 20 | 21 | 8.3 Populations for Average Days from LSAHousehold and LSAExit 22 | */ 23 | 24 | if (select LSAScope from lsa_Report) <> 3 25 | begin 26 | 27 | truncate table tlsa_AveragePops 28 | 29 | insert into tlsa_AveragePops (PopID, Cohort, Step) 30 | select 0, Cohort, '8.3.1' 31 | from tlsa_CohortDates cd 32 | where cd.Cohort between -2 and 1 33 | 34 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 35 | select distinct 10, 1, hh.HoHID, hh.HHType, '8.3.2' 36 | from tlsa_Household hh 37 | where hh.HHAdultAge = 18 and hh.HHType = 1 38 | 39 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 40 | select distinct 11, 1, hh.HoHID, hh.HHType, '8.3.3' 41 | from tlsa_Household hh 42 | where hh.HHAdultAge = 24 and hh.HHType = 1 43 | 44 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 45 | select distinct 12, 1, hh.HoHID, hh.HHType, '8.3.4' 46 | from tlsa_Household hh 47 | where hh.HHType = 2 and hh.HHParent = 1 and HHAdultAge in (18,24) 48 | 49 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 50 | select distinct 13, 1, hh.HoHID, hh.HHType, '8.3.5' 51 | from tlsa_Household hh 52 | where hh.HHVet = 1 53 | 54 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 55 | select distinct 14, 1, hh.HoHID, hh.HHType, '8.3.6' 56 | from tlsa_Household hh 57 | where hh.HHVet = 0 and hh.HHAdultAge in (25, 55) and hh.HHType = 1 58 | 59 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 60 | select distinct 15, 1, hh.HoHID, hh.HHType, '8.3.7' 61 | from tlsa_Household hh 62 | where hh.HHChronic = 1 63 | 64 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 65 | select distinct 16, 1, hh.HoHID, hh.HHType, '8.3.8' 66 | from tlsa_Household hh 67 | where hh.HHChronic in (1,2) 68 | 69 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 70 | select distinct 17, 1, hh.HoHID, hh.HHType, '8.3.9' 71 | from tlsa_Household hh 72 | where hh.HHChronic in (0,3) 73 | 74 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 75 | select distinct 18, 1, hh.HoHID, hh.HHType, '8.3.10' 76 | from tlsa_Household hh 77 | where hh.HHDisability = 1 78 | 79 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 80 | select distinct 19, 1, hh.HoHID, hh.HHType, '8.3.11' 81 | from tlsa_Household hh 82 | where hh.HHFleeingDV = 1 83 | 84 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 85 | select distinct 20, 1, hh.HoHID, hh.HHType, '8.3.12' 86 | from tlsa_Household hh 87 | where hh.Stat = 1 88 | 89 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 90 | select distinct 21, 1, hh.HoHID, hh.HHType, '8.3.13' 91 | from tlsa_Household hh 92 | where hh.Stat = 2 93 | 94 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 95 | select distinct 22, 1, hh.HoHID, hh.HHType, '8.3.14' 96 | from tlsa_Household hh 97 | where hh.PSHMoveIn = 1 98 | 99 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 100 | select distinct 101 | case when hh.HoHRaceEthnicity = 1 then 23 102 | when hh.HoHRaceEthnicity = 16 then 24 103 | when hh.HoHRaceEthnicity = 2 then 25 104 | when hh.HoHRaceEthnicity = 26 then 26 105 | when hh.HoHRaceEthnicity = 3 then 27 106 | when hh.HoHRaceEthnicity = 36 then 28 107 | when hh.HoHRaceEthnicity = 6 then 29 108 | when hh.HoHRaceEthnicity = 7 then 30 109 | when hh.HoHRaceEthnicity = 67 then 31 110 | when hh.HoHRaceEthnicity = 4 then 32 111 | when hh.HoHRaceEthnicity = 46 then 33 112 | when hh.HoHRaceEthnicity = 5 then 34 113 | when hh.HoHRaceEthnicity = 56 then 35 114 | when hh.HoHRaceEthnicity >=12 and hh.HoHRaceEthnicity not in (98,99) and cast(hh.HoHRaceEthnicity as nvarchar) not like '%6%' then 36 115 | when hh.HoHRaceEthnicity >=126 and cast(hh.HoHRaceEthnicity as nvarchar) like '%6%' then 37 116 | else null end 117 | , 1, hh.HoHID, hh.HHType, '8.3.15' 118 | from tlsa_Household hh 119 | where hh.HoHRaceEthnicity not in (98,99) 120 | 121 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 122 | select distinct 38, 1, hh.HoHID, hh.HHType, '8.3.16' 123 | from tlsa_Household hh 124 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%1%' 125 | 126 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 127 | select distinct 39, 1, hh.HoHID, hh.HHType, '8.3.17' 128 | from tlsa_Household hh 129 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%2%' 130 | 131 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 132 | select distinct 40, 1, hh.HoHID, hh.HHType, '8.3.18' 133 | from tlsa_Household hh 134 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%3%' 135 | 136 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 137 | select distinct 41, 1, hh.HoHID, hh.HHType, '8.3.19' 138 | from tlsa_Household hh 139 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%6%' 140 | 141 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 142 | select distinct 42, 1, hh.HoHID, hh.HHType, '8.3.20' 143 | from tlsa_Household hh 144 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%7%' 145 | 146 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 147 | select distinct 43, 1, hh.HoHID, hh.HHType, '8.3.21' 148 | from tlsa_Household hh 149 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%4%' 150 | 151 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 152 | select distinct 44, 1, hh.HoHID, hh.HHType, '8.3.22' 153 | from tlsa_Household hh 154 | where cast(hh.HoHRaceEthnicity as nvarchar) like '%5%' 155 | 156 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 157 | select distinct 45, 1, hh.HoHID, hh.HHType, '8.3.23' 158 | from tlsa_Household hh 159 | where hh.HHAdultAge = 55 and hh.HHType = 1 160 | 161 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 162 | select distinct 46, 1, hh.HoHID, hh.HHType, '8.3.24' 163 | from tlsa_Household hh 164 | where hh.HHParent = 1 and hh.HHType = 3 165 | 166 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 167 | select distinct 47, 1, hh.HoHID, hh.HHType, '8.3.25' 168 | from tlsa_Household hh 169 | where hh.HHChild = 3 and hh.HHType = 2 170 | 171 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 172 | select distinct 48, 1, hh.HoHID, hh.HHType, '8.3.26' 173 | from tlsa_Household hh 174 | where hh.HHFleeingDV = 2 175 | 176 | -- End LSAHousehold populations / begin LSAExit populations 177 | 178 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 179 | select distinct 10, ex.Cohort, ex.HoHID, ex.HHType, '8.3.27' 180 | from tlsa_Exit ex 181 | where ex.HHAdultAge = 18 and ex.HHType = 1 182 | 183 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 184 | select distinct 11, ex.Cohort, ex.HoHID, ex.HHType, '8.3.28' 185 | from tlsa_Exit ex 186 | where ex.HHAdultAge = 24 and ex.HHType = 1 187 | 188 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 189 | select distinct 12, ex.Cohort, ex.HoHID, ex.HHType, '8.3.29' 190 | from tlsa_Exit ex 191 | where ex.HHType = 2 and ex.HHParent = 1 and HHAdultAge in (18,24) 192 | 193 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 194 | select distinct 13, ex.Cohort, ex.HoHID, ex.HHType, '8.3.30' 195 | from tlsa_Exit ex 196 | where ex.HHVet = 1 197 | 198 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 199 | select distinct 14, ex.Cohort, ex.HoHID, ex.HHType, '8.3.31' 200 | from tlsa_Exit ex 201 | where ex.HHVet = 0 and ex.HHAdultAge in (25, 55) and ex.HHType = 1 202 | 203 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 204 | select distinct 15, ex.Cohort, ex.HoHID, ex.HHType, '8.3.32' 205 | from tlsa_Exit ex 206 | where ex.HHChronic = 1 207 | 208 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 209 | select distinct 16, ex.Cohort, ex.HoHID, ex.HHType, '8.3.33' 210 | from tlsa_Exit ex 211 | where ex.HHChronic in (1,2) 212 | 213 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 214 | select distinct 17, ex.Cohort, ex.HoHID, ex.HHType, '8.3.34' 215 | from tlsa_Exit ex 216 | where ex.HHChronic in (0,3) 217 | 218 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 219 | select distinct 18, ex.Cohort, ex.HoHID, ex.HHType, '8.3.35' 220 | from tlsa_Exit ex 221 | where ex.HHDisability = 1 222 | 223 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 224 | select distinct 19, ex.Cohort, ex.HoHID, ex.HHType, '8.3.36' 225 | from tlsa_Exit ex 226 | where ex.HHFleeingDV = 1 227 | 228 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 229 | select distinct 20, ex.Cohort, ex.HoHID, ex.HHType, '8.3.37' 230 | from tlsa_Exit ex 231 | where ex.Stat = 1 232 | 233 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 234 | select distinct 21, ex.Cohort, ex.HoHID, ex.HHType, '8.3.38' 235 | from tlsa_Exit ex 236 | where ex.Stat = 2 237 | 238 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 239 | select distinct 240 | case when ex.HoHRaceEthnicity = 1 then 23 241 | when ex.HoHRaceEthnicity = 16 then 24 242 | when ex.HoHRaceEthnicity = 2 then 25 243 | when ex.HoHRaceEthnicity = 26 then 26 244 | when ex.HoHRaceEthnicity = 3 then 27 245 | when ex.HoHRaceEthnicity = 36 then 28 246 | when ex.HoHRaceEthnicity = 6 then 29 247 | when ex.HoHRaceEthnicity = 7 then 30 248 | when ex.HoHRaceEthnicity = 67 then 31 249 | when ex.HoHRaceEthnicity = 4 then 32 250 | when ex.HoHRaceEthnicity = 46 then 33 251 | when ex.HoHRaceEthnicity = 5 then 34 252 | when ex.HoHRaceEthnicity = 56 then 35 253 | when ex.HoHRaceEthnicity >=12 and ex.HoHRaceEthnicity not in (98,99) and cast(ex.HoHRaceEthnicity as nvarchar) not like '%6%' then 36 254 | when ex.HoHRaceEthnicity >=126 and cast(ex.HoHRaceEthnicity as nvarchar) like '%6%' then 37 255 | else null end 256 | , ex.Cohort, ex.HoHID, ex.HHType, '8.3.39' 257 | from tlsa_Exit ex 258 | where ex.HoHRaceEthnicity not in (98,99) 259 | 260 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 261 | select distinct 38, ex.Cohort, ex.HoHID, ex.HHType, '8.3.40' 262 | from tlsa_Exit ex 263 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%1%' 264 | 265 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 266 | select distinct 39, ex.Cohort, ex.HoHID, ex.HHType, '8.3.41' 267 | from tlsa_Exit ex 268 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%2%' 269 | 270 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 271 | select distinct 40, ex.Cohort, ex.HoHID, ex.HHType, '8.3.42' 272 | from tlsa_Exit ex 273 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%3%' 274 | 275 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 276 | select distinct 41, ex.Cohort, ex.HoHID, ex.HHType, '8.3.43' 277 | from tlsa_Exit ex 278 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%6%' 279 | 280 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 281 | select distinct 42, ex.Cohort, ex.HoHID, ex.HHType, '8.3.44' 282 | from tlsa_Exit ex 283 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%7%' 284 | 285 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 286 | select distinct 43, ex.Cohort, ex.HoHID, ex.HHType, '8.3.45' 287 | from tlsa_Exit ex 288 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%4%' 289 | 290 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 291 | select distinct 44, ex.Cohort, ex.HoHID, ex.HHType, '8.3.46' 292 | from tlsa_Exit ex 293 | where cast(ex.HoHRaceEthnicity as nvarchar) like '%5%' 294 | 295 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 296 | select distinct 45, ex.Cohort, ex.HoHID, ex.HHType, '8.3.47' 297 | from tlsa_Exit ex 298 | where ex.HHAdultAge = 55 and ex.HHType = 1 299 | 300 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 301 | select distinct 46, ex.Cohort, ex.HoHID, ex.HHType, '8.3.48' 302 | from tlsa_Exit ex 303 | where ex.HHParent = 1 and ex.HHType = 3 304 | 305 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 306 | select distinct 47, ex.Cohort, ex.HoHID, ex.HHType, '8.3.49' 307 | from tlsa_Exit ex 308 | where ex.AC3Plus = 1 and ex.HHType = 2 309 | 310 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 311 | select distinct 48, ex.Cohort, ex.HoHID, ex.HHType, '8.3.50' 312 | from tlsa_Exit ex 313 | where ex.HHFleeingDV = 2 314 | 315 | insert into tlsa_AveragePops (PopID, Cohort, HoHID, HHType, Step) 316 | select distinct rp.PopID, p1.Cohort, p1.HoHID, p1.HHType, '8.3.51' 317 | from ref_RowPopulations rp 318 | inner join tlsa_AveragePops p1 on p1.PopID = rp.Pop1 319 | inner join tlsa_AveragePops p2 on p2.PopID = rp.Pop2 320 | and p1.Cohort = p2.Cohort 321 | and p1.HHType = p2.HHType and p1.HoHID = p2.HoHID 322 | 323 | /* 324 | 8.4-8.7 Average Days from LSAHousehold 325 | */ 326 | 327 | truncate table lsa_Calculated 328 | 329 | insert into lsa_Calculated (Value, Cohort, Universe, HHType 330 | , Population, SystemPath, ReportRow, ReportID, Step) 331 | select case rv.RowID 332 | when 1 then avg(hh.ESDays) 333 | when 2 then avg(hh.THDays) 334 | when 3 then avg(hh.ESTDays) 335 | when 4 then avg(hh.RRHPSHPreMoveInDays) 336 | when 5 then avg(hh.SystemHomelessDays) 337 | when 6 then avg(hh.Other3917Days) 338 | when 7 then avg(hh.TotalHomelessDays) 339 | when 8 then avg(hh.RRHHousedDays) 340 | when 9 then avg(hh.SystemDaysNotPSHHoused) 341 | when 10 then avg(hh.PSHHousedDays) 342 | when 11 then avg(hh.PSHHousedDays) 343 | when 12 then avg(hh.RRHPreMoveInDays) 344 | when 13 then avg(hh.RRHPreMoveInDays) 345 | when 14 then avg(hh.RRHPreMoveInDays) 346 | when 15 then avg(hh.RRHHousedDays) 347 | else avg(hh.RRHHousedDays) end, 348 | rv.Cohort, rv.Universe, ph.HHType, 349 | rp.PopID, rv.SystemPath, rv.RowID, 350 | hh.ReportID, '8.4-8.7' 351 | from tlsa_Household hh 352 | inner join tlsa_AveragePops pop on (pop.PopID = 0 or (pop.HHType = hh.HHType and pop.HoHID = hh.HoHID)) and pop.Cohort = 1 353 | inner join ref_RowPopulations rp on rp.PopID = pop.PopID and rp.RowMin between 1 and 16 354 | inner join ref_PopHHTypes ph on ph.PopID = rp.PopID and (ph.HHType = hh.HHType or ph.HHType = 0) 355 | inner join ref_RowValues rv on rv.RowID between rp.RowMin and rp.RowMax 356 | and ((rp.ByPath is null and rv.SystemPath = -1) 357 | or (rp.ByPath = 1 and rv.SystemPath <> -1 and rv.SystemPath = hh.SystemPath)) 358 | where rv.RowID between 1 and 16 359 | and case rv.RowID 360 | when 1 then hh.ESDays 361 | when 2 then hh.THDays 362 | when 3 then hh.ESTDays 363 | when 4 then hh.RRHPSHPreMoveInDays 364 | when 5 then hh.SystemHomelessDays 365 | when 6 then hh.Other3917Days 366 | when 7 then hh.TotalHomelessDays 367 | when 8 then hh.RRHHousedDays 368 | when 9 then hh.SystemDaysNotPSHHoused 369 | when 10 then hh.PSHHousedDays 370 | when 11 then hh.PSHHousedDays 371 | when 12 then hh.RRHPreMoveInDays 372 | when 13 then hh.RRHPreMoveInDays 373 | when 14 then hh.RRHPreMoveInDays 374 | when 15 then hh.RRHHousedDays 375 | else hh.RRHHousedDays end > 0 376 | and (rv.RowID <> 10 or (hh.PSHMoveIn in (1,2) and hh.PSHStatus in (12,22))) 377 | and (rv.RowID <> 11 or (hh.PSHMoveIn in (1,2) and hh.PSHStatus in (11,21))) 378 | and (rv.RowID <> 12 or (hh.RRHStatus in (12,22) and hh.RRHMoveIn = 0)) 379 | and (rv.RowID <> 13 or (hh.RRHStatus in (11,21) and hh.RRHMoveIn = 0)) 380 | and (rv.RowID <> 14 or (hh.RRHStatus > 2 and hh.RRHMoveIn in (1,2))) 381 | and (rv.RowID <> 15 or (hh.RRHStatus in (12,22) and hh.RRHMoveIn in (1,2))) 382 | and (rv.RowID <> 16 or (hh.RRHStatus in (11,21) and hh.RRHMoveIn in (1,2))) 383 | group by rv.RowID, rv.Cohort, rv.Universe, ph.HHType, 384 | rp.PopID, rv.SystemPath, rv.RowID, 385 | hh.ReportID 386 | 387 | /* 388 | 8.8-8.10 Average Days from LSAExit 389 | */ 390 | 391 | 392 | insert into lsa_Calculated (Value, Cohort, Universe, HHType 393 | , Population, SystemPath, ReportRow, ReportID, Step) 394 | select avg(ex.ReturnTime), 395 | rv.Cohort, rv.Universe, ph.HHType, 396 | rp.PopID, rv.SystemPath, rv.RowID, 397 | ex.ReportID, '8.8-8.10' 398 | from tlsa_Exit ex 399 | inner join tlsa_AveragePops pop on pop.Cohort = ex.Cohort and (pop.PopID = 0 or (pop.HHType = ex.HHType and pop.HoHID = ex.HoHID)) 400 | inner join ref_RowPopulations rp on rp.PopID = pop.PopID 401 | inner join ref_PopHHTypes ph on ph.PopID = rp.PopID and (ph.HHType = 0 or ph.HHType = ex.HHType) 402 | inner join ref_RowValues rv on rv.RowID between rp.RowMin and rp.RowMax 403 | and (rv.SystemPath = -1 or rv.SystemPath = ex.SystemPath) 404 | and rv.Cohort = ex.Cohort 405 | and rv.Universe = case 406 | when ex.ExitTo between 400 and 499 then 2 407 | when ex.ExitTo between 100 and 399 then 3 408 | else 4 end 409 | where (rv.RowID between 18 and 36 or rv.RowID between 63 and 66) 410 | and ex.ReturnTime > 0 411 | and (rv.RowID not between 18 and 22 or ex.ExitFrom = (rv.RowID - 16)) 412 | and (rv.RowID <> 63 or ex.ExitFrom = 7) 413 | and (rv.RowID <> 64 or ex.ExitFrom = 8) 414 | and (rv.RowID <> 65 or ex.ExitFrom = 9) 415 | and (rv.RowID <> 66 or ex.ExitFrom = 10) 416 | and (rv.RowID <> 36 or ex.SystemPath <> -1) 417 | group by rv.RowID, rv.Cohort, rv.Universe, ph.HHType, 418 | rp.PopID, rv.SystemPath, rv.RowID, 419 | ex.ReportID 420 | 421 | /* 422 | 8.11 Average Days to Return by Exit Destination 423 | */ 424 | 425 | insert into lsa_Calculated (Value, Cohort, Universe, HHType 426 | , Population, SystemPath, ReportRow, ReportID, Step) 427 | select avg(ex.ReturnTime), 428 | rv.Cohort, rv.Universe, ph.HHType, 429 | rp.PopID, rv.SystemPath, rv.RowID, 430 | ex.ReportID, '8.11' 431 | from tlsa_Exit ex 432 | inner join tlsa_AveragePops pop on pop.Cohort = ex.Cohort and (pop.PopID = 0 or (pop.HHType = ex.HHType and pop.HoHID = ex.HoHID)) 433 | inner join ref_RowPopulations rp on rp.PopID = pop.PopID 434 | inner join ref_PopHHTypes ph on ph.PopID = rp.PopID and (ph.HHType = 0 or ph.HHType = ex.HHType) 435 | inner join ref_RowValues rv on rv.RowID between rp.RowMin and rp.RowMax 436 | and rv.RowID = case ex.ExitTo 437 | when 101 then 101 438 | when 116 then 102 439 | when 118 then 103 440 | when 204 then 104 441 | when 205 then 105 442 | when 206 then 106 443 | when 207 then 107 444 | when 215 then 108 445 | when 225 then 109 446 | when 302 then 110 447 | when 312 then 111 448 | when 313 then 112 449 | when 314 then 113 450 | when 327 then 114 451 | when 329 then 115 452 | when 332 then 116 453 | when 410 then 117 454 | when 411 then 118 455 | when 419 then 119 456 | when 420 then 120 457 | when 421 then 121 458 | when 422 then 122 459 | when 423 then 123 460 | when 426 then 124 461 | when 428 then 125 462 | when 431 then 126 463 | when 433 then 127 464 | when 434 then 128 465 | when 436 then 129 466 | when 437 then 130 467 | when 438 then 131 468 | when 439 then 132 469 | when 440 then 133 470 | when 24 then 134 471 | when 98 then 135 472 | else 136 end 473 | and rv.Cohort = ex.Cohort 474 | and rv.Universe = case 475 | when ex.ExitTo between 400 and 499 then 2 476 | when ex.ExitTo between 100 and 399 then 3 477 | else 4 end 478 | where rv.RowID between 101 and 136 479 | and ex.ReturnTime > 0 480 | group by rv.RowID, rv.Cohort, rv.Universe, ph.HHType, 481 | rp.PopID, rv.SystemPath, rv.RowID, 482 | ex.ReportID 483 | 484 | end -- END IF LSAScope <> HIC 485 | 486 | /* 487 | End LSACalculated Averages for LSAHousehold and LSAExit 488 | */ -------------------------------------------------------------------------------- /09 LSACalculated AHAR Counts.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 09 LSACalculated AHAR Counts.sql 4 | 5 | FY2024 Changes 6 | 7 | Section 9.6 - Get OPH Point-in-Time Counts for HIC 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | Uses static reference tables: 12 | ref_RowValues - Required Cohort, Universe, SystemPath values for each RowID 13 | ref_RowPopulations - Required Populations for each RowID 14 | and (for rows 1-9) whether the RowID is required by SystemPath for the Population 15 | ref_PopHHTypes - HHTypes required in LSACalculated for each Population by PopID 16 | Populates and references: 17 | tlsa_CountPops - By PopID -- HouseholdID and/or PersonalID for each population member 18 | 19 | 9 Populations for AHAR Counts 20 | */ 21 | truncate table tlsa_CountPops 22 | 23 | insert into tlsa_CountPops (PopID, Step) 24 | values (0, '9.1.0') 25 | 26 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 27 | select distinct 10, HouseholdID, '9.1.1' 28 | from tlsa_HHID 29 | where AHAR = 1 and HHAdultAge = 18 30 | and ActiveHHType = 1 31 | 32 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 33 | select distinct 11, HouseholdID, '9.1.2' 34 | from tlsa_HHID 35 | where AHAR = 1 and HHAdultAge = 24 36 | and ActiveHHType = 1 37 | 38 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 39 | select distinct 12, HouseholdID, '9.1.3' 40 | from tlsa_HHID 41 | where AHAR = 1 and HHParent = 1 and HHAdultAge in (18,24) 42 | and ActiveHHType = 2 43 | 44 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 45 | select distinct 13, HouseholdID, '9.1.4' 46 | from tlsa_HHID 47 | where AHAR = 1 and HHVet = 1 48 | 49 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 50 | select distinct 14, HouseholdID, '9.1.5' 51 | from tlsa_HHID 52 | where AHAR = 1 and HHVet = 0 and HHAdultAge in (25,55) 53 | and ActiveHHType = 1 54 | 55 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 56 | select distinct 15, HouseholdID, '9.1.6' 57 | from tlsa_HHID 58 | where AHAR = 1 and HHChronic = 1 59 | 60 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 61 | select distinct 18, HouseholdID, '9.1.7' 62 | from tlsa_HHID 63 | where AHAR = 1 and HHDisability = 1 64 | 65 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 66 | select distinct 19, HouseholdID, '9.1.8' 67 | from tlsa_HHID 68 | where AHAR = 1 and HHFleeingDV = 1 69 | 70 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 71 | select distinct 45, HouseholdID, '9.1.9' 72 | from tlsa_HHID 73 | where AHAR = 1 and HHAdultAge = 55 74 | and ActiveHHType = 1 75 | 76 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 77 | select distinct 46, HouseholdID, '9.1.10' 78 | from tlsa_HHID 79 | where AHAR = 1 and HHParent = 1 and ActiveHHType = 3 80 | 81 | insert into tlsa_CountPops (PopID, HouseholdID, Step) 82 | select distinct 48, HouseholdID, '9.1.11' 83 | from tlsa_HHID 84 | where AHAR = 1 and HHFleeingDV = 2 85 | 86 | insert into tlsa_CountPops (PopID, PersonalID, Step) 87 | select distinct 50, n.PersonalID, '9.1.12' 88 | from tlsa_Enrollment n 89 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 90 | where n.AHAR = 1 and lp.VetStatus = 1 91 | 92 | insert into tlsa_CountPops (PopID, PersonalID, HouseholdID, Step) 93 | select distinct 51, hhid.HoHID, hhid.HouseholdID, '9.1.13' 94 | from tlsa_HHID hhid 95 | where hhid.AHAR = 1 and hhid.HHAdultAge in (18,24) and hhid.HHParent = 1 and hhid.ActiveHHType = 2 96 | 97 | insert into tlsa_CountPops (PopID, PersonalID, HouseholdID, Step) 98 | select distinct 52, hhid.HoHID, hhid.HouseholdID, '9.1.14' 99 | from tlsa_HHID hhid 100 | where hhid.AHAR = 1 and hhid.HHParent = 1 and hhid.ActiveHHType = 3 101 | 102 | insert into tlsa_CountPops (PopID, PersonalID, Step) 103 | select distinct 53, n.PersonalID, '9.1.15' 104 | from tlsa_Enrollment n 105 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 106 | where n.AHAR = 1 and lp.DisabilityStatus = 1 and ( 107 | (lp.CHTime = 365 and lp.CHTimeStatus in (1,2)) 108 | or (lp.CHTime = 400 and lp.CHTimeStatus = 2)) 109 | 110 | insert into tlsa_CountPops (PopID, PersonalID, Step) 111 | select distinct 54, n.PersonalID, '9.1.16' 112 | from tlsa_Enrollment n 113 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 114 | where n.AHAR = 1 and lp.DisabilityStatus = 1 115 | 116 | insert into tlsa_CountPops (PopID, PersonalID, Step) 117 | select distinct 55, n.PersonalID, '9.1.17' 118 | from tlsa_Enrollment n 119 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 120 | where n.AHAR = 1 and lp.DVStatus = 1 121 | 122 | insert into tlsa_CountPops (PopID, PersonalID, Step) 123 | select distinct 124 | case when lp.RaceEthnicity = 1 then 56 125 | when lp.RaceEthnicity = 16 then 57 126 | when lp.RaceEthnicity = 2 then 58 127 | when lp.RaceEthnicity = 26 then 59 128 | when lp.RaceEthnicity = 3 then 60 129 | when lp.RaceEthnicity = 36 then 61 130 | when lp.RaceEthnicity = 6 then 62 131 | when lp.RaceEthnicity = 7 then 63 132 | when lp.RaceEthnicity = 67 then 64 133 | when lp.RaceEthnicity = 4 then 65 134 | when lp.RaceEthnicity = 46 then 66 135 | when lp.RaceEthnicity = 5 then 67 136 | when lp.RaceEthnicity = 56 then 68 137 | when lp.RaceEthnicity >= 12 and lp.RaceEthnicity not in (98,99) and cast(lp.RaceEthnicity as nvarchar) not like '%6%' then 69 138 | when lp.RaceEthnicity >= 126 and cast(lp.RaceEthnicity as nvarchar) like '%6%' then 70 else null end 139 | , n.PersonalID, '9.1.18' 140 | from tlsa_Enrollment n 141 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 142 | where n.AHAR = 1 and lp.RaceEthnicity not in (98,99) 143 | 144 | insert into tlsa_CountPops (PopID, PersonalID, Step) 145 | select distinct 71, n.PersonalID, '9.1.19' 146 | from tlsa_Enrollment n 147 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 148 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%1%' 149 | 150 | insert into tlsa_CountPops (PopID, PersonalID, Step) 151 | select distinct 72, n.PersonalID, '9.1.20' 152 | from tlsa_Enrollment n 153 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 154 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%2%' 155 | 156 | insert into tlsa_CountPops (PopID, PersonalID, Step) 157 | select distinct 73, n.PersonalID, '9.1.21' 158 | from tlsa_Enrollment n 159 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 160 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%3%' 161 | 162 | insert into tlsa_CountPops (PopID, PersonalID, Step) 163 | select distinct 74, n.PersonalID, '9.1.22' 164 | from tlsa_Enrollment n 165 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 166 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%6%' 167 | 168 | insert into tlsa_CountPops (PopID, PersonalID, Step) 169 | select distinct 75, n.PersonalID, '9.1.23' 170 | from tlsa_Enrollment n 171 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 172 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%7%' 173 | 174 | insert into tlsa_CountPops (PopID, PersonalID, Step) 175 | select distinct 76, n.PersonalID, '9.1.24' 176 | from tlsa_Enrollment n 177 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 178 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%4%' 179 | 180 | insert into tlsa_CountPops (PopID, PersonalID, Step) 181 | select distinct 77, n.PersonalID, '9.1.25' 182 | from tlsa_Enrollment n 183 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 184 | where n.AHAR = 1 and cast(lp.RaceEthnicity as nvarchar) like '%5%' 185 | 186 | 187 | insert into tlsa_CountPops (PopID, PersonalID, Step) 188 | select distinct case lp.Gender 189 | when 0 then 78 190 | when 1 then 79 191 | when 2 then 80 192 | when 5 then 81 193 | when 4 then 82 194 | when 6 then 83 195 | when 3 then 84 196 | else 85 end, n.PersonalID, '9.1.26' 197 | from tlsa_Enrollment n 198 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 199 | where n.AHAR = 1 and lp.Gender not in (98, 99) 200 | 201 | insert into tlsa_CountPops (PopID, PersonalID, Step) 202 | select distinct case max(n.ActiveAge) 203 | when 0 then 86 204 | when 2 then 87 205 | when 5 then 88 206 | when 17 then 89 207 | when 21 then 90 208 | when 24 then 91 209 | when 34 then 92 210 | when 44 then 93 211 | when 54 then 94 212 | when 64 then 95 213 | else 96 end 214 | , n.PersonalID, '9.1.27' 215 | from tlsa_Enrollment n 216 | where n.ActiveAge not in (98,99) and n.AHAR = 1 217 | group by n.PersonalID 218 | 219 | 220 | insert into tlsa_CountPops (PopID, PersonalID, Step) 221 | select distinct 97, n.PersonalID, '9.1.28' 222 | from tlsa_Enrollment n 223 | inner join tlsa_Person lp on lp.PersonalID = n.PersonalID 224 | where n.AHAR = 1 and lp.DVStatus in (2,3) 225 | 226 | insert into tlsa_CountPops (PopID, PersonalID, HouseholdID, Step) 227 | select distinct case when hhid.ActiveHHType = 1 and n.ActiveAge = 21 then 1190 228 | when hhid.ActiveHHType = 1 and n.ActiveAge = 24 then 1191 229 | when hhid.ActiveHHType = 2 and n.ActiveAge = 21 then 1290 230 | else 1291 end 231 | , n.PersonalID, hhid.HouseholdID, '9.1.29' 232 | from tlsa_Enrollment n 233 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 234 | where hhid.HHAdultAge in (18,24) 235 | and n.ActiveAge in (21,24) 236 | and (ActiveHHType = 1 or (ActiveHHType = 2 and HHParent = 1)) 237 | and n.AHAR = 1 238 | 239 | insert into tlsa_CountPops (PopID, PersonalID, HouseholdID, Step) 240 | select distinct rp.PopID, p1.PersonalID, p1.HouseholdID, '9.1.30' 241 | from ref_RowPopulations rp 242 | inner join tlsa_CountPops p1 on p1.PopID = rp.Pop1 243 | inner join tlsa_CountPops p2 on p2.PopID = rp.Pop2 and p2.PersonalID = p1.PersonalID 244 | where rp.RowMin >= 53 and rp.RowMax <> 64 245 | 246 | /* 247 | 9.2 Identify Point-in-Time Cohorts for AHAR Counts 248 | */ 249 | 250 | update n 251 | set PITOctober = (select distinct case when cd.Cohort is null then 0 else 1 end 252 | from tlsa_CohortDates cd 253 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 254 | and n.EntryDate <= cd.CohortStart and cd.Cohort = 10) 255 | , PITJanuary = (select distinct case when cd.Cohort is null then 0 else 1 end 256 | from tlsa_CohortDates cd 257 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 258 | and n.EntryDate <= cd.CohortStart and cd.Cohort = 11) 259 | , PITApril = (select distinct case when cd.Cohort is null then 0 else 1 end 260 | from tlsa_CohortDates cd 261 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 262 | and n.EntryDate <= cd.CohortStart and cd.Cohort = 12) 263 | , PITJuly = (select distinct case when cd.Cohort is null then 0 else 1 end 264 | from tlsa_CohortDates cd 265 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 266 | and n.EntryDate <= cd.CohortStart and cd.Cohort = 13) 267 | , Step = '9.2.1' 268 | from tlsa_Enrollment n 269 | where n.LSAProjectType in (0,2,8) 270 | and n.AHAR = 1 271 | 272 | update n 273 | set n.PITOctober = PIT.PITOctober 274 | , n.PITJanuary = PIT.PITJanuary 275 | , n.PITApril = PIT.PITApril 276 | , n.PITJuly = PIT.PITJuly 277 | , n.Step = '9.2.2' 278 | from tlsa_Enrollment n 279 | inner join (select distinct nbn.EnrollmentID 280 | , PITOctober = max(case when cd1.Cohort is null then 0 else 1 end) 281 | , PITJanuary = max(case when cd2.Cohort is null then 0 else 1 end) 282 | , PITApril = max(case when cd3.Cohort is null then 0 else 1 end) 283 | , PITJuly = max(case when cd4.Cohort is null then 0 else 1 end) 284 | from tlsa_Enrollment nbn 285 | inner join tlsa_CohortDates cd on cd.CohortEnd >= nbn.EntryDate 286 | and (nbn.ExitDate is NULL or nbn.ExitDate > cd.CohortStart) 287 | inner join hmis_Services bn on bn.EnrollmentID = nbn.EnrollmentID 288 | and nbn.EntryDate <= bn.DateProvided 289 | and (nbn.ExitDate is NULL or nbn.ExitDate > bn.DateProvided) 290 | left outer join tlsa_CohortDates cd1 on cd1.CohortStart = bn.DateProvided and cd1.Cohort = 10 291 | left outer join tlsa_CohortDates cd2 on cd2.CohortStart = bn.DateProvided and cd2.Cohort = 11 292 | left outer join tlsa_CohortDates cd3 on cd3.CohortStart = bn.DateProvided and cd3.Cohort = 12 293 | left outer join tlsa_CohortDates cd4 on cd4.CohortStart = bn.DateProvided and cd4.Cohort = 13 294 | where nbn.LSAProjectType = 1 295 | and nbn.AHAR = 1 296 | group by nbn.EnrollmentID) PIT on PIT.EnrollmentID = n.EnrollmentID 297 | 298 | update n 299 | set PITOctober = (select distinct case when cd.Cohort is null then 0 else 1 end 300 | from tlsa_CohortDates cd 301 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 302 | and n.MoveInDate <= cd.CohortStart and cd.Cohort = 10) 303 | , PITJanuary = (select distinct case when cd.Cohort is null then 0 else 1 end 304 | from tlsa_CohortDates cd 305 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 306 | and n.MoveInDate <= cd.CohortStart and cd.Cohort = 11) 307 | , PITApril = (select distinct case when cd.Cohort is null then 0 else 1 end 308 | from tlsa_CohortDates cd 309 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 310 | and n.MoveInDate <= cd.CohortStart and cd.Cohort = 12) 311 | , PITJuly = (select distinct case when cd.Cohort is null then 0 else 1 end 312 | from tlsa_CohortDates cd 313 | where (cd.CohortStart < n.ExitDate or n.ExitDate is NULL) 314 | and n.MoveInDate <= cd.CohortStart and cd.Cohort = 13) 315 | , Step = '9.2.3' 316 | from tlsa_Enrollment n 317 | where n.LSAProjectType in (3,13) 318 | and n.AHAR = 1 319 | 320 | /* 321 | 9.3 Counts of People and Households by Project and Household Characteristics 322 | 323 | */ 324 | 325 | delete from lsa_Calculated where ReportRow in (53,54) 326 | 327 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID 328 | , ReportRow, ReportID, Step) 329 | select distinct case when rv.RowID = 53 then count(distinct n.PersonalID) 330 | else count(distinct hhid.HoHID + cast(hhid.ActiveHHType as varchar)) end 331 | , rv.Cohort, rv.Universe, ph.HHType, rp.PopID, rv.SystemPath 332 | , case when rv.Universe = 10 then hhid.ProjectID else null end 333 | , rv.RowID, (select distinct ReportID from lsa_Report), '9.3.1' 334 | from ref_RowValues rv 335 | inner join ref_RowPopulations rp on rv.RowID between rp.RowMin and rp.RowMax 336 | inner join ref_PopHHTypes ph on ph.PopID = rp.PopID 337 | inner join tlsa_CountPops pop on rp.PopID = pop.PopID 338 | inner join tlsa_HHID hhid on (rp.PopID = 0 or hhid.HouseholdID = pop.HouseholdID) 339 | and (hhid.ActiveHHType = ph.HHType or ph.HHType = 0) 340 | and ( 341 | rv.Universe = 10 342 | or (rv.Universe = 11 and hhid.LSAProjectType in (0,1)) 343 | or (rv.Universe = 12 and hhid.LSAProjectType = 8) 344 | or (rv.Universe = 13 and hhid.LSAProjectType = 2) 345 | or (rv.Universe = 14 and hhid.LSAProjectType = 13) 346 | or (rv.Universe = 15 and hhid.LSAProjectType = 3) 347 | or (rv.Universe = 16 and hhid.LSAProjectType in (0,1,2,8)) 348 | ) 349 | inner join tlsa_Enrollment n on n.HouseholdID = hhid.HouseholdID 350 | and case rv.Cohort 351 | when 1 then n.AHAR 352 | when 10 then n.PITOctober 353 | when 11 then n.PITJanuary 354 | when 12 then n.PITApril 355 | else n.PITJuly end = 1 356 | where rv.RowID in (53,54) 357 | group by rv.RowID, rv.Cohort, rv.Universe, ph.HHType, rp.PopID, rv.SystemPath 358 | , case when rv.Universe = 10 then hhid.ProjectID else null end 359 | 360 | /* 361 | 9.4 Counts of People by Project and Personal Characteristics 362 | */ 363 | 364 | delete from lsa_Calculated where ReportRow = 55 365 | 366 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID 367 | , ReportRow, ReportID, Step) 368 | select distinct count(distinct n.PersonalID) 369 | , rv.Cohort, rv.Universe, ph.HHType, rp.PopID, rv.SystemPath 370 | , case when rv.Universe = 10 then hhid.ProjectID else null end 371 | , rv.RowID, (select distinct ReportID from lsa_Report), '9.4.1' 372 | from ref_RowValues rv 373 | inner join ref_RowPopulations rp on rv.RowID between rp.RowMin and rp.RowMax 374 | inner join ref_PopHHTypes ph on ph.PopID = rp.PopID 375 | inner join tlsa_CountPops pop on rp.PopID = pop.PopID 376 | and (rv.Universe <> 10 or rp.ByProject = 1) 377 | inner join tlsa_Enrollment n on n.PersonalID = pop.PersonalID 378 | and (n.HouseholdID = pop.HouseholdID or pop.HouseholdID is null) 379 | and case rv.Cohort 380 | when 1 then n.AHAR 381 | when 10 then n.PITOctober 382 | when 11 then n.PITJanuary 383 | when 12 then n.PITApril 384 | else n.PITJuly end = 1 385 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 386 | and (hhid.ActiveHHType = ph.HHType or ph.HHType = 0) 387 | and ( 388 | rv.Universe = 10 389 | or (rv.Universe = 11 and hhid.LSAProjectType in (0,1)) 390 | or (rv.Universe = 12 and hhid.LSAProjectType = 8) 391 | or (rv.Universe = 13 and hhid.LSAProjectType = 2) 392 | or (rv.Universe = 14 and hhid.LSAProjectType = 13) 393 | or (rv.Universe = 15 and hhid.LSAProjectType = 3) 394 | or (rv.Universe = 16 and hhid.LSAProjectType in (0,1,2,8)) 395 | ) 396 | where rv.RowID = 55 397 | group by rv.Cohort, rv.Universe, ph.HHType, rp.PopID, rv.SystemPath 398 | , case when rv.Universe = 10 then hhid.ProjectID else null end 399 | , rv.RowID 400 | 401 | /* 402 | 9.5 Counts of Bednights 403 | 404 | By ProjectID (Universe 10) 405 | Night-by-night ES - 9.5.1 406 | Entry-exit ES/TH/SH/RRH/PSH - 9.5.2 407 | By project type ES (Universe 11) - 9.5.3 408 | By project type SH/TH/RRH/PSH (Universe 12-15) - 9.5.4 409 | ES/SH/TH unduplicated (Universe 16) - 9.5.5 410 | 411 | */ 412 | 413 | -- By ProjectID (Universe 10) - night by night ES 414 | 415 | delete from lsa_Calculated where ReportRow in (56,57) 416 | 417 | 418 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID, ReportRow, ReportID, Step) 419 | select distinct count(distinct n.PersonalID + cast(bn.DateProvided as varchar)), 1, 10, ph.HHType, pop.PopID, -1 420 | , hhid.ProjectID 421 | , case when pop.PopID in (0,10,11) then 56 else 57 end 422 | , (select distinct ReportID from lsa_Report), '9.5.1' 423 | from hmis_Services bn 424 | inner join tlsa_Enrollment n on n.EnrollmentID = bn.EnrollmentID 425 | and (n.ExitDate is null or n.ExitDate > bn.DateProvided) 426 | and n.EntryDate <= bn.DateProvided 427 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 428 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 429 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 430 | or (pop.PopID = 0) 431 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 432 | inner join lsa_Report rpt on rpt.ReportStart <= bn.DateProvided and rpt.ReportEnd >= bn.DateProvided 433 | where n.LSAProjectType = 1 and bn.RecordType = 200 and bn.DateDeleted is NULL and n.AHAR = 1 434 | group by ph.HHType, hhid.ProjectID, pop.PopID 435 | 436 | -- By ProjectID (Universe 10) - entry-exit ES, SH, TH, RRH, and PSH 437 | insert into lsa_Calculated 438 | (Value, Cohort, Universe, HHType 439 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 440 | select distinct count (distinct n.PersonalID + cast(cal.theDate as nvarchar)) 441 | , 1, 10, ph.HHType 442 | , pop.PopID, -1 443 | , case when pop.PopID in (0,10,11) then 56 else 57 end 444 | , n.ProjectID 445 | , rpt.ReportID, '9.5.2' 446 | from tlsa_Enrollment n 447 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 448 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 449 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 450 | or (pop.PopID = 0) 451 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 452 | inner join lsa_Report rpt on rpt.ReportEnd >= 453 | case when n.LSAProjectType in (0,2,8) then n.EntryDate 454 | else n.MoveInDate end 455 | inner join ref_Calendar cal on cal.theDate >= 456 | case when n.LSAProjectType in (0,2,8) then n.EntryDate 457 | else n.MoveInDate end 458 | and cal.theDate >= rpt.ReportStart 459 | and cal.theDate < coalesce(n.ExitDate, dateadd(dd, 1, rpt.ReportEnd)) 460 | and n.LSAProjectType in (0,2,3,8,13) 461 | where n.AHAR = 1 462 | group by n.ProjectID, rpt.ReportID, ph.HHType, pop.PopID 463 | 464 | -- All ES (Universe 11) 465 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID, ReportRow, ReportID, Step) 466 | select distinct count(distinct es.bn), 1, 11, es.HHType, es.PopID, -1, NULL 467 | , case when es.PopID in (0,10,11) then 56 else 57 end 468 | , (select distinct ReportID from lsa_Report), '9.5.3' 469 | from 470 | (select distinct n.PersonalID + cast(bn.DateProvided as varchar) as bn, ph.HHType as HHType, pop.PopID 471 | from hmis_Services bn 472 | inner join tlsa_Enrollment n on n.EnrollmentID = bn.EnrollmentID 473 | and (n.ExitDate is null or n.ExitDate > bn.DateProvided) 474 | and n.EntryDate <= bn.DateProvided 475 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 476 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 477 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 478 | or (pop.PopID = 0) 479 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 480 | inner join lsa_Report rpt on rpt.ReportStart <= bn.DateProvided and rpt.ReportEnd >= bn.DateProvided 481 | where hhid.LSAProjectType = 1 and bn.RecordType = 200 and bn.DateDeleted is NULL and n.AHAR = 1 482 | union all 483 | select distinct n.PersonalID + cast(cal.theDate as varchar), ph.HHType, pop.PopID 484 | from tlsa_Enrollment n 485 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 486 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 487 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 488 | or (pop.PopID = 0) 489 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 490 | inner join lsa_Report rpt on rpt.ReportEnd >= n.EntryDate 491 | inner join ref_Calendar cal on cal.theDate >= n.EntryDate 492 | and cal.theDate >= rpt.ReportStart 493 | and cal.theDate < coalesce(n.ExitDate, dateadd(dd, 1, rpt.ReportEnd)) 494 | and n.LSAProjectType = 0 495 | where n.AHAR = 1) es 496 | group by es.HHType, es.PopID 497 | 498 | -- By Project Type SH/TH/RRH/PSH (Universe 12-15) 499 | insert into lsa_Calculated 500 | (Value, Cohort, Universe, HHType 501 | , Population, SystemPath, ReportRow, ReportID, Step) 502 | select distinct count (distinct n.PersonalID + cast(cal.theDate as nvarchar)) 503 | , 1, case n.LSAProjectType 504 | when 8 then 12 505 | when 2 then 13 506 | when 13 then 14 else 15 end 507 | , ph.HHType 508 | , pop.PopID, -1 509 | , case when pop.PopID in (0,10,11) then 56 else 57 end 510 | , rpt.ReportID, '9.5.4' 511 | from tlsa_Enrollment n 512 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 513 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 514 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 515 | or (pop.PopID = 0) 516 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 517 | inner join lsa_Report rpt on rpt.ReportEnd >= 518 | case when n.LSAProjectType in (2,8) then n.EntryDate 519 | else n.MoveInDate end 520 | inner join ref_Calendar cal on cal.theDate >= 521 | case when n.LSAProjectType in (2,8) then n.EntryDate 522 | else n.MoveInDate end 523 | and cal.theDate >= rpt.ReportStart 524 | and cal.theDate < coalesce(n.ExitDate, dateadd(dd, 1, rpt.ReportEnd)) 525 | and n.LSAProjectType in (2,3,8,13) 526 | where n.AHAR = 1 527 | group by case n.LSAProjectType 528 | when 8 then 12 529 | when 2 then 13 530 | when 13 then 14 else 15 end, rpt.ReportID, ph.HHType, pop.PopID 531 | 532 | -- Unduplicated ES/SH/TH (Universe 16) 533 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID, ReportRow, ReportID, Step) 534 | select distinct count(distinct est.bn), 1, 16, est.HHType, est.PopID, -1, NULL 535 | , case when est.PopID in (0,10,11) then 56 else 57 end 536 | , (select distinct ReportID from lsa_Report), '9.5.5' 537 | from 538 | (select distinct n.PersonalID + cast(bn.DateProvided as varchar) as bn, ph.HHType as HHType, pop.PopID 539 | from hmis_Services bn 540 | inner join tlsa_Enrollment n on n.EnrollmentID = bn.EnrollmentID and n.EntryDate <= bn.DateProvided 541 | and (n.ExitDate is null or n.ExitDate > bn.DateProvided) 542 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 543 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 544 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 545 | or (pop.PopID = 0) 546 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 547 | inner join lsa_Report rpt on rpt.ReportStart <= bn.DateProvided and rpt.ReportEnd >= bn.DateProvided 548 | where hhid.LSAProjectType = 1 and bn.RecordType = 200 and bn.DateDeleted is NULL and n.AHAR = 1 549 | union all 550 | select distinct n.PersonalID + cast(cal.theDate as varchar), ph.HHType, pop.PopID 551 | from tlsa_Enrollment n 552 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 553 | inner join tlsa_CountPops pop on (pop.HouseholdID = n.HouseholdID and pop.PopID in (10,11)) 554 | or (pop.PersonalID = n.PersonalID and pop.PopID in (50,53)) 555 | or (pop.PopID = 0) 556 | inner join ref_PopHHTypes ph on ph.PopID = pop.PopID and (ph.HHType = 0 or ph.HHType = hhid.ActiveHHType) 557 | inner join lsa_Report rpt on rpt.ReportEnd >= n.EntryDate 558 | inner join ref_Calendar cal on cal.theDate >= n.EntryDate 559 | and cal.theDate >= rpt.ReportStart 560 | and cal.theDate < coalesce(n.ExitDate, dateadd(dd, 1, rpt.ReportEnd)) 561 | and n.LSAProjectType in (0,2,8) 562 | where n.AHAR = 1) est 563 | group by est.HHType, est.PopID 564 | 565 | 566 | /* 567 | 9.6. Get OPH Point-In-Time Counts for HIC 568 | 569 | */ 570 | 571 | delete from lsa_Calculated where Step = '9.6' 572 | 573 | insert into lsa_Calculated (Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID, ReportRow, ReportID, Step) 574 | select count(distinct hh.PersonalID), 1, 10, 0, 0, -1, p.ProjectID, 53, rpt.ReportID, '9.6' 575 | from lsa_Project p 576 | inner join lsa_HMISParticipation hp on hp.ProjectID = p.ProjectID 577 | inner join lsa_Report rpt on rpt.ReportStart >= hp.HMISParticipationStatusStartDate 578 | and (hp.HMISParticipationStatusEndDate is null or hp.HMISParticipationStatusEndDate > rpt.ReportStart) 579 | inner join hmis_Enrollment hn on hn.ProjectID = p.ProjectID and hn.EntryDate <= rpt.ReportStart and hn.MoveInDate <= rpt.ReportStart 580 | and hn.MoveInDate >= hn.EntryDate and hn.RelationshipToHoH = 1 581 | and hn.EnrollmentCoC = rpt.ReportCoC 582 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 583 | inner join (select hhn.ProjectID, hhn.HouseholdID, hhn.PersonalID, hhn.EntryDate as StartDate, coalesce(hhx.ExitDate, getdate()) as EndDate 584 | from hmis_Enrollment hhn 585 | left outer join hmis_Exit hhx on hhx.EnrollmentID = hhn.EnrollmentID 586 | where hhn.DateDeleted is null and hhx.DateDeleted is null) hh on hh.HouseholdID = hn.HouseholdID 587 | and hh.StartDate <= rpt.ReportStart and hh.EndDate > ReportStart 588 | where rpt.LSAScope = 3 and hp.HMISParticipationType = 1 and p.ProjectType in (9,10) 589 | and (hx.ExitDate is null or hx.ExitDate > rpt.ReportStart) 590 | and hn.DateDeleted is null and hx.DateDeleted is null 591 | group by p.ProjectID, rpt.ReportID 592 | -------------------------------------------------------------------------------- /10 LSACalculated Data Quality.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 10 LSACalculated Data Quality.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode)/ 10 | 11 | 12 | 10.2 Get Counts of Enrollments Active after Operating End Date by ProjectID 13 | */ 14 | 15 | delete from lsa_Calculated where ReportRow in (901,902) 16 | 17 | insert into lsa_Calculated 18 | (Value, Cohort, Universe, HHType 19 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 20 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1 21 | , case when hx.ExitDate is null then 901 22 | else 902 end 23 | , p.ProjectID, cd.ReportID, '10.2' 24 | from tlsa_Enrollment n 25 | left outer join hmis_Exit hx on hx.EnrollmentID = n.EnrollmentID 26 | and hx.DateDeleted is null 27 | inner join hmis_Project p on p.ProjectID = n.ProjectID 28 | inner join tlsa_CohortDates cd on cd.Cohort = 1 29 | and p.OperatingEndDate between cd.CohortStart and cd.CohortEnd 30 | where (hx.ExitDate is null or hx.ExitDate > p.OperatingEndDate) 31 | group by case when hx.ExitDate is null then 901 32 | else 902 end 33 | , p.ProjectID, cd.ReportID 34 | 35 | /* 36 | 10.3 Get Counts of Night-by-Night Enrollments with Exit Date Discrepancies 37 | */ 38 | 39 | delete from lsa_Calculated where ReportRow in (903,904) 40 | 41 | insert into lsa_Calculated 42 | (Value, Cohort, Universe, HHType 43 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 44 | select count (distinct hn.EnrollmentID), 1, 10, 0, 0, -1 45 | , case when hx.ExitDate is null or hx.ExitDate > cd.CohortEnd then 903 46 | else 904 end 47 | , p.ProjectID, cd.ReportID, '10.3' 48 | from tlsa_Enrollment n 49 | inner join tlsa_CohortDates cd on cd.Cohort = 1 50 | inner join tlsa_HHID hhid on hhid.HouseholdID = n.HouseholdID 51 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 52 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 53 | and hx.DateDeleted is NULL 54 | inner join hmis_Project p on p.ProjectID = hn.ProjectID and p.ProjectType = 1 and p.ContinuumProject = 1 55 | left outer join (select svc.EnrollmentID, max(svc.DateProvided) as LastBednight 56 | from hmis_Services svc 57 | inner join hmis_Enrollment nbn on nbn.EnrollmentID = svc.EnrollmentID 58 | inner join hmis_Project p on p.ProjectID = nbn.ProjectID 59 | and p.ProjectType = 1 60 | and (p.OperatingEndDate is null or p.OperatingEndDate >= DateProvided) 61 | inner join tlsa_CohortDates cd on cd.Cohort = 1 62 | and svc.DateProvided between cd.CohortStart and cd.CohortEnd 63 | where svc.RecordType = 200 and svc.DateDeleted is null 64 | group by svc.EnrollmentID 65 | ) bn on bn.EnrollmentID = hhid.EnrollmentID 66 | where ((hx.ExitDate is null or hx.ExitDate > cd.CohortEnd) and bn.LastBednight <= dateadd(dd, -90, cd.CohortEnd)) 67 | or (hx.ExitDate between cd.CohortStart and cd.CohortEnd and hx.ExitDate <> dateadd(dd, 1, bn.LastBednight)) 68 | group by case when hx.ExitDate is null or hx.ExitDate > cd.CohortEnd then 903 69 | else 904 end 70 | , p.ProjectID, cd.ReportID 71 | 72 | /* 73 | 10.4 Get Counts of Households with no Enrollment CoC Record 74 | */ 75 | 76 | delete from lsa_Calculated where ReportRow = 905 77 | 78 | insert into lsa_Calculated 79 | (Value, Cohort, Universe, HHType 80 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 81 | select count (distinct hn.HouseholdID), 1, 10, 0, 0, -1, 905, p.ProjectID, rpt.ReportID, '10.4' 82 | from lsa_Report rpt 83 | inner join hmis_Enrollment hn on hn.EntryDate <= rpt.ReportEnd 84 | inner join lsa_Project p on p.ProjectID = hn.ProjectID and p.ProjectType not in (9,10) 85 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 86 | and hx.DateDeleted is null 87 | left outer join hmis_Enrollment hoh on hoh.HouseholdID = hn.HouseholdID 88 | and hoh.RelationshipToHoH = 1 89 | and hoh.DateDeleted is null 90 | where hn.DateDeleted is null 91 | and hoh.EnrollmentCoC is null 92 | and (hx.ExitDate is null or 93 | (hx.ExitDate >= rpt.ReportStart and hx.ExitDate > hn.EntryDate)) 94 | group by p.ProjectID, rpt.ReportID 95 | 96 | /* 97 | 10.5 DQ – Enrollments in non-participating projects 98 | */ 99 | delete from lsa_Calculated where ReportRow = 906 100 | 101 | insert into lsa_Calculated 102 | (Value, Cohort, Universe, HHType 103 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 104 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 906, n.ProjectID, rpt.ReportID, '10.5' 105 | from lsa_Report rpt 106 | inner join hmis_Enrollment n on n.EntryDate <= rpt.ReportEnd 107 | inner join hmis_Enrollment hoh on hoh.HouseholdID = n.HouseholdID 108 | inner join lsa_Project p on p.ProjectID = n.ProjectID and p.ProjectType not in (9,10) 109 | left outer join hmis_Exit x on x.EnrollmentID = n.EnrollmentID and x.DateDeleted is null 110 | left outer join lsa_HMISParticipation part on part.ProjectID = n.ProjectID 111 | and part.HMISParticipationType = 1 112 | and part.HMISParticipationStatusStartDate <= n.EntryDate 113 | and (part.HMISParticipationStatusEndDate is null 114 | or part.HMISParticipationStatusEndDate >= x.ExitDate 115 | or (x.ExitDate is null and part.HMISParticipationStatusEndDate > rpt.ReportEnd)) 116 | where hoh.RelationshipToHoH = 1 and hoh.EnrollmentCoC = rpt.ReportCoC and part.ProjectID is null 117 | and (x.ExitDate is null 118 | or (x.ExitDate >= ReportStart and x.ExitDate > n.EntryDate)) 119 | and n.DateDeleted is null and hoh.DateDeleted is null 120 | group by n.ProjectID, rpt.ReportID 121 | /* 122 | 10.6 DQ – Enrollments without exactly one HoH 123 | */ 124 | delete from lsa_Calculated where ReportRow = 907 125 | 126 | insert into lsa_Calculated 127 | (Value, Cohort, Universe, HHType 128 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 129 | select count (distinct hn.EnrollmentID), 1, 10, 0, 0, -1, 907, hn.ProjectID, rpt.ReportID, '10.6' 130 | from lsa_Report rpt 131 | inner join hmis_Enrollment hn on hn.EntryDate <= rpt.ReportEnd 132 | inner join lsa_Project p on p.ProjectID = hn.ProjectID 133 | inner join hmis_Enrollment coc on coc.HouseholdID = hn.HouseholdID and coc.EnrollmentCoC = rpt.ReportCoC 134 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 135 | and hx.DateDeleted is null 136 | left outer join (select hoh.HouseholdID, count(hoh.PersonalID) as hoh 137 | from hmis_Enrollment hoh 138 | where hoh.RelationshipToHoH = 1 and hoh.DateDeleted is null 139 | group by hoh.HouseholdID) counthoh on counthoh.HouseholdID = hn.HouseholdID 140 | where (counthoh.HouseholdID is null or counthoh.hoh > 1) 141 | and p.ProjectType not in (9,10) 142 | and hn.DateDeleted is null 143 | and (hx.ExitDate is null or 144 | (hx.ExitDate >= rpt.ReportStart and hx.ExitDate > hn.EntryDate)) 145 | group by hn.ProjectID, rpt.ReportID 146 | /* 147 | 10.7 DQ – Relationship to HoH 148 | */ 149 | delete from lsa_Calculated where ReportRow = 908 150 | 151 | insert into lsa_Calculated 152 | (Value, Cohort, Universe, HHType 153 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 154 | select count (distinct hn.EnrollmentID), 1, 10, 0, 0, -1, 908, hn.ProjectID, rpt.ReportID, '10.7' 155 | from lsa_Report rpt 156 | inner join hmis_Enrollment hn on hn.EntryDate <= rpt.ReportEnd 157 | inner join lsa_Project p on p.ProjectID = hn.ProjectID 158 | inner join hmis_Enrollment coc on coc.HouseholdID = hn.HouseholdID and coc.EnrollmentCoC = rpt.ReportCoC 159 | left outer join hmis_Exit hx on hx.EnrollmentID = hn.EnrollmentID 160 | and hx.DateDeleted is null 161 | where (hn.RelationshipToHoH is null or hn.RelationshipToHoH not between 1 and 5) 162 | and p.ProjectType not in (9,10) 163 | and hn.DateDeleted is null 164 | and (hx.ExitDate is null or 165 | (hx.ExitDate >= rpt.ReportStart and hx.ExitDate > hn.EntryDate)) 166 | group by hn.ProjectID, rpt.ReportID 167 | /* 168 | 10.8 DQ – Household Entry 169 | */ 170 | delete from lsa_Calculated where ReportRow = 909 171 | 172 | insert into lsa_Calculated 173 | (Value, Cohort, Universe, HHType 174 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 175 | select count (distinct hh.HouseholdID), 1, 10, 0, 0, -1, 909, hh.ProjectID, rpt.ReportID, '10.8' 176 | from lsa_Report rpt 177 | inner join tlsa_HHID hh on hh.EntryDate <= rpt.ReportEnd 178 | where hh.Active = 1 179 | group by hh.ProjectID, rpt.ReportID 180 | /* 181 | 10.9 DQ – Client Entry 182 | */ 183 | delete from lsa_Calculated where ReportRow = 910 184 | 185 | insert into lsa_Calculated 186 | (Value, Cohort, Universe, HHType 187 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 188 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 910, n.ProjectID, rpt.ReportID, '10.9' 189 | from lsa_Report rpt 190 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 191 | where n.Active = 1 192 | group by n.ProjectID, rpt.ReportID 193 | /* 194 | 10.10 DQ – Adult/HoH Entry 195 | */ 196 | delete from lsa_Calculated where ReportRow = 911 197 | 198 | insert into lsa_Calculated 199 | (Value, Cohort, Universe, HHType 200 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 201 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 911, n.ProjectID, rpt.ReportID, '10.10' 202 | from lsa_Report rpt 203 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 204 | where n.Active = 1 205 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 206 | group by n.ProjectID, rpt.ReportID 207 | 208 | /* 209 | 10.11 DQ – Client Exit 210 | */ 211 | delete from lsa_Calculated where ReportRow = 912 212 | 213 | insert into lsa_Calculated 214 | (Value, Cohort, Universe, HHType 215 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 216 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 912, n.ProjectID, rpt.ReportID, '10.11' 217 | from lsa_Report rpt 218 | inner join tlsa_Enrollment n on n.ExitDate <= rpt.ReportEnd 219 | where n.Active = 1 220 | group by n.ProjectID, rpt.ReportID 221 | /* 222 | 10.12 DQ – Disabling Condition 223 | */ 224 | delete from lsa_Calculated where ReportRow = 913 225 | 226 | insert into lsa_Calculated 227 | (Value, Cohort, Universe, HHType 228 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 229 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 913, n.ProjectID, rpt.ReportID, '10.12' 230 | from lsa_Report rpt 231 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 232 | where n.Active = 1 and n.DisabilityStatus = 99 233 | group by n.ProjectID, rpt.ReportID 234 | /* 235 | 10.13 DQ – Living Situation 236 | */ 237 | delete from lsa_Calculated where ReportRow = 914 238 | 239 | insert into lsa_Calculated 240 | (Value, Cohort, Universe, HHType 241 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 242 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 914, n.ProjectID, rpt.ReportID, '10.13' 243 | from lsa_Report rpt 244 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 245 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 246 | where n.Active = 1 247 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 248 | and (hn.LivingSituation in (8,9,99) or hn.LivingSituation is NULL) 249 | group by n.ProjectID, rpt.ReportID 250 | 251 | /* 252 | 10.14 DQ – Length of Stay 253 | */ 254 | delete from lsa_Calculated where ReportRow = 915 255 | 256 | insert into lsa_Calculated 257 | (Value, Cohort, Universe, HHType 258 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 259 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 915, n.ProjectID, rpt.ReportID, '10.14' 260 | from lsa_Report rpt 261 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 262 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 263 | where n.Active = 1 264 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 265 | and (hn.LengthOfStay in (8,9,99) or hn.LengthOfStay is NULL) 266 | group by n.ProjectID, rpt.ReportID 267 | /* 268 | 10.15 DQ – Date ES/SH/Street Homelessness Started 269 | */ 270 | delete from lsa_Calculated where ReportRow = 916 271 | 272 | insert into lsa_Calculated 273 | (Value, Cohort, Universe, HHType 274 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 275 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 916, n.ProjectID, rpt.ReportID, '10.15' 276 | from lsa_Report rpt 277 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 278 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 279 | where n.Active = 1 280 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 281 | and (hn.DateToStreetESSH > hn.EntryDate 282 | or (hn.DateToStreetESSH is null 283 | and (n.LSAProjectType in (0,1,8) 284 | or hn.LivingSituation in (101,116,118) 285 | or hn.PreviousStreetESSH = 1 286 | ) 287 | ) 288 | ) 289 | group by n.ProjectID, rpt.ReportID 290 | /* 291 | 10.16 DQ – Times ES/SH/Street Homeless Last 3 Years 292 | */ 293 | delete from lsa_Calculated where ReportRow = 917 294 | 295 | insert into lsa_Calculated 296 | (Value, Cohort, Universe, HHType 297 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 298 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 917, n.ProjectID, rpt.ReportID, '10.16' 299 | from lsa_Report rpt 300 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 301 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 302 | where n.Active = 1 303 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 304 | and (hn.TimesHomelessPastThreeYears is NULL 305 | or hn.TimesHomelessPastThreeYears not in (1,2,3,4)) 306 | and (n.LSAProjectType in (0,1,8) 307 | or hn.LivingSituation in (101,116,118) 308 | or hn.PreviousStreetESSH = 1) 309 | group by n.ProjectID, rpt.ReportID 310 | /* 311 | 10.17 DQ – Months ES/SH/Street Homeless Last 3 Years 312 | */ 313 | delete from lsa_Calculated where ReportRow = 918 314 | 315 | insert into lsa_Calculated 316 | (Value, Cohort, Universe, HHType 317 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 318 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 918, n.ProjectID, rpt.ReportID, '10.17' 319 | from lsa_Report rpt 320 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 321 | inner join hmis_Enrollment hn on hn.EnrollmentID = n.EnrollmentID 322 | where n.Active = 1 323 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 324 | and (hn.MonthsHomelessPastThreeYears is NULL 325 | or hn.MonthsHomelessPastThreeYears not between 101 and 113) 326 | and (n.LSAProjectType in (0,1,8) 327 | or hn.LivingSituation in (101,116,118) 328 | or hn.PreviousStreetESSH = 1) 329 | group by n.ProjectID, rpt.ReportID 330 | /* 331 | 10.18 DQ – Destination 332 | */ 333 | delete from lsa_Calculated where ReportRow = 919 334 | 335 | insert into lsa_Calculated 336 | (Value, Cohort, Universe, HHType 337 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 338 | select count (distinct n.EnrollmentID), 1, 10, 0, 0, -1, 919, n.ProjectID, rpt.ReportID, '10.18' 339 | from lsa_Report rpt 340 | inner join tlsa_Enrollment n on n.ExitDate <= rpt.ReportEnd 341 | inner join hmis_Exit x on x.EnrollmentID = n.EnrollmentID and x.DateDeleted is null 342 | where n.Active = 1 343 | and (x.Destination is NULL or x.Destination in (8,9,17,30,99) 344 | or (x.Destination = 435 and x.DestinationSubsidyType is NULL)) 345 | group by n.ProjectID, rpt.ReportID 346 | /* 347 | 10.19 DQ – Date of Birth 348 | */ 349 | 350 | delete from lsa_Calculated where ReportRow = 920 351 | 352 | insert into lsa_Calculated 353 | (Value, Cohort, Universe, HHType 354 | , Population, SystemPath, ReportRow, ProjectID, ReportID, Step) 355 | select count (distinct n.PersonalID), 1, 10, 0, 0, -1, 920, n.ProjectID, rpt.ReportID, '10.19' 356 | from lsa_Report rpt 357 | inner join tlsa_Enrollment n on n.EntryDate <= rpt.ReportEnd 358 | where n.Active = 1 and n.ActiveAge in (98,99) 359 | group by n.ProjectID, rpt.ReportID 360 | 361 | /* 362 | 10.20 LSACalculated 363 | 364 | NOTE: Export of lsa_Calculated data to LSACalculated.csv has to exclude the Step column. 365 | 366 | alter lsa_Calculated drop column Step 367 | 368 | select Value, Cohort, Universe, HHType, Population, SystemPath, ProjectID, ReportRow, ReportID 369 | from lsa_Calculated 370 | */ 371 | -------------------------------------------------------------------------------- /11 LSAReport DQ and ReportDate.sql: -------------------------------------------------------------------------------- 1 | /* 2 | LSA FY2024 Sample Code 3 | Name: 11 LSAReport DQ and ReportDate.sql 4 | 5 | FY2024 Changes 6 | 7 | None 8 | 9 | (Detailed revision history maintained at https://github.com/HMIS/LSASampleCode) 10 | 11 | Please note that if this code is used in production, the first statement in section 11.6 12 | should be reviewed and updated if necessary to set SSNValid to 0 include any system default 13 | for missing SSN values that would not be identified by the existing code. 14 | 15 | 11.1 HMIS HouseholdIDs With No CoC Identifier Active in LSA Projects During Report Period 16 | */ 17 | update rpt 18 | set rpt.NoCoC = (select count (distinct n.HouseholdID) 19 | from hmis_Enrollment n 20 | inner join lsa_Project p on p.ProjectID = n.ProjectID 21 | and p.ProjectType in (0,1,2,3,8,13) 22 | inner join lsa_Organization org on org.OrganizationID = p.OrganizationID 23 | and org.VictimServiceProvider = 0 24 | left outer join hmis_Exit x on x.EnrollmentID = n.EnrollmentID 25 | and x.DateDeleted is null 26 | where n.EntryDate <= rpt.ReportEnd 27 | and (x.ExitDate is null or x.ExitDate >= rpt.ReportStart) 28 | and n.RelationshipToHoH = 1 29 | and (n.EnrollmentCoC is null 30 | or n.EnrollmentCoC not in (select coc.CoCCode 31 | from hmis_ProjectCoC coc 32 | where coc.ProjectID = p.ProjectID 33 | and coc.DateDeleted is null) 34 | ) 35 | and n.DateDeleted is null 36 | ) 37 | from lsa_Report rpt 38 | 39 | /* 40 | 11.2 HMIS HouseholdIDs Without Exactly One HoH Active in LSA Projects During Report Period 41 | */ 42 | 43 | update rpt 44 | set rpt.NotOneHoH = (select count (distinct n.HouseholdID) 45 | from hmis_Enrollment n 46 | inner join lsa_Project p on p.ProjectID = n.ProjectID 47 | and p.ProjectType in (0,1,2,3,8,13) 48 | inner join lsa_Organization org on org.OrganizationID = p.OrganizationID 49 | and org.VictimServiceProvider = 0 50 | inner join (select distinct hh.HouseholdID 51 | from hmis_Enrollment hh 52 | inner join lsa_Report coc on coc.ReportCoC = hh.EnrollmentCoC 53 | where hh.DateDeleted is null 54 | ) coc on coc.HouseholdID = n.HouseholdID 55 | left outer join hmis_Exit x on x.EnrollmentID = n.EnrollmentID 56 | and x.DateDeleted is null 57 | left outer join (select hn.HouseholdID, count(distinct hn.EnrollmentID) as hoh 58 | from hmis_Enrollment hn 59 | where hn.RelationshipToHoH = 1 and hn.DateDeleted is null 60 | group by hn.HouseholdID 61 | ) hoh on hoh.HouseholdID = n.HouseholdID 62 | where n.EntryDate <= rpt.ReportEnd 63 | and (x.ExitDate is null or x.ExitDate >= rpt.ReportStart) 64 | and n.DateDeleted is null 65 | and (hoh.hoh <> 1 or hoh.HouseholdID is null) 66 | ) 67 | from lsa_Report rpt 68 | 69 | /* 70 | 11.3 HMIS Enrollments Associated with LSA Households But Excluded from LSA Due to Invalid RelatioshipToHoH 71 | */ 72 | 73 | update rpt 74 | set rpt.RelationshipToHoH = (select count(distinct hn.EnrollmentID) 75 | from hmis_Enrollment hn 76 | inner join tlsa_HHID hhid on hhid.HouseholdID = hn.HouseholdID 77 | left outer join hmis_Exit x on x.EnrollmentID = hn.EnrollmentID 78 | and x.DateDeleted is null 79 | where hhid.Active = 1 80 | and hn.EntryDate <= rpt.ReportEnd 81 | and (x.ExitDate is null or x.ExitDate >= rpt.ReportStart) 82 | and hn.DateDeleted is null 83 | and (hn.RelationshipToHoH is null or hn.RelationshipToHoH not in (1,2,3,4,5)) 84 | ) 85 | from lsa_Report rpt 86 | 87 | /* 88 | 11.4 Invalid HMIS Move-In Dates for RRH and PSH Enrollments Included in LSA 89 | */ 90 | 91 | update rpt 92 | set rpt.MoveInDate = 93 | (select count(distinct hhid.EnrollmentID) 94 | from tlsa_HHID hhid 95 | inner join hmis_Enrollment hn on hn.EnrollmentID = hhid.EnrollmentID 96 | where hhid.LSAProjectType in (3,13,15) 97 | and hhid.Active = 1 98 | and hhid.MoveInDate is null 99 | and hn.MoveInDate <= rpt.ReportEnd 100 | ) 101 | from lsa_Report rpt 102 | 103 | /* 104 | 11.5 Counts of Clients/Households/Enrollments 105 | */ 106 | 107 | update rpt 108 | set rpt.UnduplicatedClient = (select count(distinct PersonalID) 109 | from tlsa_Person) 110 | , rpt.HouseholdEntry = (select count(distinct HouseholdID) 111 | from tlsa_HHID 112 | where Active = 1) 113 | , rpt.ClientEntry = (select count(distinct EnrollmentID) 114 | from tlsa_Enrollment 115 | where Active = 1) 116 | , rpt.AdultHoHEntry = (select count(distinct EnrollmentID) 117 | from tlsa_Enrollment 118 | where Active = 1 119 | and (ActiveAge between 18 and 65 or RelationshipToHoH = 1)) 120 | , rpt.ClientExit = (select count(distinct EnrollmentID) 121 | from tlsa_Enrollment 122 | where Active = 1 and ExitDate is not NULL) 123 | from lsa_Report rpt 124 | 125 | /* 126 | 11.6 SSN Issues 127 | */ 128 | 129 | update lp 130 | set lp.SSNValid = case when c.SSNDataQuality in (8,9) then 9 131 | when SUBSTRING(c.SSN,1,3) in ('000','666') 132 | or LEN(c.SSN) <> 9 133 | or SUBSTRING(c.SSN,4,2) = '00' 134 | or SUBSTRING(c.SSN,6,4) ='0000' 135 | or c.SSN is null 136 | or c.SSN = '' 137 | or c.SSN like '%[^0-9]%' 138 | or left(c.SSN,1) = '9' 139 | or c.SSN in ('111111111','222222222','333333333','444444444' 140 | ,'555555555','777777777','888888888' 141 | , '123456789', '234567890', '345678901', '456789012', '567890123' 142 | , '678901234', '789012345', '890123456', '901234567') 143 | then 0 else 1 end 144 | from tlsa_Person lp 145 | inner join hmis_Client c on c.PersonalID = lp.PersonalID 146 | 147 | update rpt 148 | set SSNNotProvided = (select count(distinct PersonalID) 149 | from tlsa_Person 150 | where SSNValid = 9) 151 | , SSNMissingOrInvalid = (select count(distinct PersonalID) 152 | from tlsa_Person 153 | where SSNValid = 0) 154 | from lsa_Report rpt 155 | 156 | update rpt 157 | set rpt.ClientSSNNotUnique = case when ssn.people is null then 0 else ssn.people end 158 | , rpt.DistinctSSNValueNotUnique = case when ssn.SSNs is null then 0 else ssn.SSNs end 159 | from lsa_Report rpt 160 | left outer join 161 | (select lp.ReportID, count(distinct lp.PersonalID) as people, count(distinct c.SSN) as SSNs 162 | from tlsa_Person lp 163 | inner join hmis_Client c on c.PersonalID = lp.PersonalID 164 | inner join (select distinct dupe.PersonalID, dupeSSN.SSN 165 | from tlsa_Person dupe 166 | inner join hmis_Client dupeSSN on dupeSSN.PersonalID = dupe.PersonalID 167 | ) other on other.PersonalID <> lp.PersonalID and other.SSN = c.SSN 168 | where lp.SSNValid = 1 169 | group by lp.ReportID) ssn on ssn.ReportID = rpt.ReportID 170 | 171 | /* 172 | 11.7 Enrollment Data Issues 173 | */ 174 | 175 | update rpt 176 | set rpt.DisablingCond = (select count(distinct n.EnrollmentID) 177 | from tlsa_Enrollment n 178 | where n.Active = 1 179 | and n.DisabilityStatus = 99 180 | ) 181 | from lsa_Report rpt 182 | 183 | update rpt 184 | set rpt.LivingSituation = (select count(distinct n.EnrollmentID) 185 | from tlsa_Enrollment n 186 | inner join hmis_Enrollment hn on n.EnrollmentID = hn.EnrollmentID 187 | where n.Active = 1 188 | and (hn.LivingSituation is null or hn.LivingSituation in (8,9,99)) 189 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65)) 190 | from lsa_Report rpt 191 | 192 | update rpt 193 | set rpt.LengthOfStay = (select count(distinct n.EnrollmentID) 194 | from tlsa_Enrollment n 195 | inner join hmis_Enrollment hn on n.EnrollmentID = hn.EnrollmentID 196 | where n.Active = 1 197 | and (hn.LengthOfStay is null or hn.LengthOfStay in (8,9,99)) 198 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65)) 199 | from lsa_Report rpt 200 | 201 | update rpt 202 | set rpt.HomelessDate = (select count(distinct n.EnrollmentID) 203 | from tlsa_Enrollment n 204 | inner join hmis_Enrollment hn on n.EnrollmentID = hn.EnrollmentID 205 | where n.Active = 1 206 | and (hn.DateToStreetESSH > hn.EntryDate 207 | or (hn.DateToStreetESSH is null 208 | and (n.LSAProjectType in (0,1,8) 209 | or hn.LivingSituation between 100 and 199 210 | or hn.PreviousStreetESSH = 1 211 | ) 212 | ) 213 | ) 214 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65) 215 | ) 216 | from lsa_Report rpt 217 | 218 | update rpt 219 | set rpt.TimesHomeless = (select count(distinct n.EnrollmentID) 220 | from tlsa_Enrollment n 221 | inner join hmis_Enrollment hn on n.EnrollmentID = hn.EnrollmentID 222 | where n.Active = 1 223 | and (hn.TimesHomelessPastThreeYears is NULL 224 | or hn.TimesHomelessPastThreeYears not in (1,2,3,4)) 225 | and (n.LSAProjectType in (0,1,8) 226 | or hn.LivingSituation between 100 and 199 227 | or hn.PreviousStreetESSH = 1) 228 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65)) 229 | from lsa_Report rpt 230 | 231 | update rpt 232 | set rpt.MonthsHomeless = (select count(distinct n.EnrollmentID) 233 | from tlsa_Enrollment n 234 | inner join hmis_Enrollment hn on n.EnrollmentID = hn.EnrollmentID 235 | where n.Active = 1 236 | and (hn.MonthsHomelessPastThreeYears is NULL 237 | or hn.MonthsHomelessPastThreeYears not between 101 and 113) 238 | and (n.LSAProjectType in (0,1,8) 239 | or hn.LivingSituation between 100 and 199 240 | or hn.PreviousStreetESSH = 1) 241 | and (n.RelationshipToHoH = 1 or n.ActiveAge between 18 and 65)) 242 | from lsa_Report rpt 243 | 244 | update rpt 245 | set rpt.Destination = (select count(distinct n.EnrollmentID) 246 | from tlsa_Enrollment n 247 | left outer join hmis_Exit x on x.EnrollmentID = n.EnrollmentID 248 | and x.DateDeleted is null 249 | where n.Active = 1 and n.ExitDate is not null 250 | and (x.Destination is null 251 | or x.Destination in (8,9,17,30,99) 252 | or (x.Destination = 435 and x.DestinationSubsidyType is null)) 253 | ) 254 | from lsa_Report rpt 255 | 256 | /* 257 | 11.8 Set ReportDate for LSAReport 258 | */ 259 | update lsa_Report set ReportDate = getdate() -------------------------------------------------------------------------------- /Full Flag List for Vendors.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Full Flag List for Vendors.xlsx -------------------------------------------------------------------------------- /LSA Data Dictionary FY2024.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/LSA Data Dictionary FY2024.xlsx -------------------------------------------------------------------------------- /LSA Programming Specifications FY2024 - Annotated.docx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/LSA Programming Specifications FY2024 - Annotated.docx -------------------------------------------------------------------------------- /LSA Programming Specifications FY2024.docx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/LSA Programming Specifications FY2024.docx -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | # LSA Sample Code Repository 3 | 4 | The Longitudinal System Analysis (LSA) is: 5 | * A report to the US Department of Housing and Urban Development (HUD) as 6 | * A zip file containing 12 Comma-Separated Values (CSV) files 7 | * Generated by a Homeless Management Information System (HMIS) 8 | * For Continuums of Care for the Homeless (CoCs) 9 | * Submitted annually via HUD's Homelessness Data Exchange (HDX 2.0) 10 | * Used to produce HUD's Annual Homelessness Assessment Report (AHAR) to Congress and 11 | * Provides the data for Stella, HUD's strategy and analysis tool for CoCs, available on HDX 2.0. 12 | 13 | This repository is provided as a supplement to the [LSA Report Specifications](https://www.hudexchange.info/resource/5726/lsa-report-specifications-and-tools/) for the benefit of HMIS vendors. Its purpose is to provide a space for reconciling the LSA specifications to the HMIS Data Standards as required to maintain a compliant HMIS product. The LSA Report Specifications remain the central reference for vendors in regards to creating and maintaining LSA reporting. 14 | 15 | ## Documentation 16 | The final versions of these documents are available on the [HUD Exchange](https://www.hudexchange.info/resource/5726/lsa-report-specifications-and-tools/). The documents here are working versions that change more frequently and prior to release on the HUD Exchange. 17 | * LSA Programming Specifications (usually referred to as 'the specs') - a Word document with detailed business logic and step-by-step instructions for producing the LSA based on HMIS data. 18 | * LSA Data Dictionary - an Excel file that lists file names, columns, and valid values for the 12 CSV files included in an LSA upload. 19 | 20 | ## Code 21 | The sample code is SQL, and written in SQL Server. Originally, it was not intended for public release -- it was written concurrent with the first version of the specs (FY2018) as a check to make sure the specs were specific enough. It was released on GitHub as a reference. 22 | 23 | ## Sample Data 24 | The Sample Data file above includes five ZIP files: 25 | * Sample HMIS Data - HMIS CSV files 26 | * Sample LSA Output - LSA CSV files generated by the LSA Sample Code based on the HMIS CSV files using general parameters 27 | * Sample LSA Temp Tables - CSV files of exported data from the temporary tables created by the LSA sample code 28 | * Sample HIC Output - LSA CSV files generated by the LSA sample code based on the HMIS CSV files using HIC parameters 29 | * Sample HIC Temp Tables - CSV files of exported data from the temporary tables with HIC parameters 30 | 31 | # Dependencies 32 | In order to run the code as is, a user must have access to a SQL Server (or SQL Server Express) database with: 33 | * Permissions that allow creating tables, inserting records, and exporting CSV files. 34 | * HMIS data in tables modeled after [HMIS CSV FY2024](https://files.hudexchange.info/resources/documents/HMIS-CSV-Format-Specifications-2024.pdf). Naming conventions for tables use an hmis_ prefix with the CSV file name -- e.g., hmis_Project. 35 | 36 | Specifically, the LSA sample code requires the tables listed below. Only records where DateDeleted is NULL are relevant. 37 | * hmis_Organization 38 | * hmis_Project 39 | * hmis_Funder 40 | * hmis_ProjectCoC 41 | * hmis_Inventory 42 | * hmis_Affiliation 43 | * hmis_HMISParticipation 44 | * hmis_Client 45 | * hmis_Enrollment 46 | * hmis_Exit 47 | * hmis_Services 48 | * hmis_HealthAndDV 49 | * hmis_Disabilities 50 | 51 | 52 | 53 | -------------------------------------------------------------------------------- /Sample Data/Sample Data.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample Data.zip -------------------------------------------------------------------------------- /Sample Data/Sample HIC Output.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample HIC Output.zip -------------------------------------------------------------------------------- /Sample Data/Sample HIC Temp Tables.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample HIC Temp Tables.zip -------------------------------------------------------------------------------- /Sample Data/Sample HMIS Data.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample HMIS Data.zip -------------------------------------------------------------------------------- /Sample Data/Sample LSA Output.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample LSA Output.zip -------------------------------------------------------------------------------- /Sample Data/Sample LSA Temp Tables.zip: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/HMIS/LSASampleCode/06f8ee2fc88b653d5ccd4de54190c369924ca03a/Sample Data/Sample LSA Temp Tables.zip --------------------------------------------------------------------------------