Stored Procedures
1proc_AddStaffRequirement 2proc_AllAbusers 3proc_AllChildren
4proc_AllParticipants 5proc_AlterLoginSysAdmin 6proc_AuditRecords
7proc_ChangeCallToNoShow 8proc_CurrentAbusers 9proc_CurrentChildren
10proc_CurrentParticipants 11proc_DeleteAbuser 12proc_DeleteAbuserAlert
13proc_DeleteAbuserIntake 14proc_DeleteAlias 15proc_DeleteAssessment
16proc_DeleteCall 17proc_DeleteChild 18proc_DeleteChildAlias
19proc_DeleteChildIntake 20proc_DeleteClientSession 21proc_DeleteCommunityMember
22proc_DeleteCredential 23proc_DeleteEmerContact 24proc_DeleteFocus
25proc_DeleteGrant 26proc_DeleteGrantor 27proc_DeleteInfoRelease
28proc_DeleteIntakeCall 29proc_DeleteIntervention 30proc_DeleteNote
31proc_DeleteParticipant 32proc_DeleteParticipantFile 33proc_DeleteParticipantIntake
34proc_DeletePhase 35proc_DeletePresentation 36proc_DeleteQuestion
37proc_DeleteQuestionnaire 38proc_DeleteReferral 39proc_DeleteReportNarrative
40proc_DeleteServiceSession 41proc_DeleteStaffMember 42proc_DeleteSurvey
43proc_DeleteTask 44proc_DeleteTrainingSession 45proc_DeleteVolunteerActivity
46proc_DuplicateDOBs 47proc_DuplicatedParticipants 48proc_EradicateAbuser
49proc_EradicateAbuserAlert 50proc_EradicateAbuserIntake 51proc_EradicateAlias
52proc_EradicateAssessment 53proc_EradicateBed 54proc_EradicateBedAssignment
55proc_EradicateCall 56proc_EradicateCampus 57proc_EradicateChild
58proc_EradicateChildAlias 59proc_EradicateChildIntake 60proc_EradicateClientSession
61proc_EradicateCommunityMember 62proc_EradicateCredential 63proc_EradicateEmergencyContact
64proc_EradicateGrant 65proc_EradicateGrantor 66proc_EradicateInfoRelease
67proc_EradicateIntake 68proc_EradicateIntervention 69proc_EradicateNewShelter
70proc_EradicateNote 71proc_EradicateParticipant 72proc_EradicateParticipantFile
73proc_EradicatePhase 74proc_EradicatePresentation 75proc_EradicateQuestionnaire
76proc_EradicateReferral 77proc_EradicateReportNarrative 78proc_EradicateRoom
79proc_EradicateRoomBedAssignment 80proc_EradicateServiceSession 81proc_EradicateShelter
82proc_EradicateStaffMember 83proc_EradicateSurvey 84proc_EradicateTrainingSession
85proc_EradicateVolunteerActivity 86proc_FillOtherArrays 87proc_FillProgramLookup
88proc_FillServiceLookup 89proc_FillStaffLookups 90proc_GetAbuser
91proc_GetAbuserAlert 92proc_GetAbuserAlerts 93proc_GetAbuserData
94proc_GetAbuserIntake 95proc_GetActivityClients 96proc_GetActivityClientsByEditDate
97proc_GetActivityParticipants 98proc_GetActivityParticipantsByEditDate 99proc_GetAlias
100proc_GetAllBeds 101proc_GetAllClientsAndIntakeData 102proc_GetAllParticipantsAndIntakeData
103proc_GetAssessment 104proc_GetAssessmentItems 105proc_GetAssessments
106proc_GetBackupData 107proc_GetBed 108proc_GetBedAssignments
109proc_GetCall 110proc_GetCallsAndWalkIns 111proc_GetChild
112proc_GetChildAlias 113proc_GetChildData 114proc_GetChildren
115proc_GetClientIntakes 116proc_GetClientNotes 117proc_GetClientReferrals
118proc_GetClients 119proc_GetClientServiceSessions 120proc_GetCommunityMember
121proc_GetCommunityMembers 122proc_GetCredential 123proc_GetCredentials
124proc_GetCurrentBedsAndAssignments 125proc_GetDeletedAbuserAlerts 126proc_GetDeletedAbuserIntakes
127proc_GetDeletedAbusers 128proc_GetDeletedAliases 129proc_GetDeletedAssessments
130proc_GetDeletedCalls 131proc_GetDeletedChildAliases 132proc_GetDeletedChildIntakes
133proc_GetDeletedChildren 134proc_GetDeletedCommunityMembers 135proc_GetDeletedCredentials
136proc_GetDeletedEmergencyContacts 137proc_GetDeletedGrantors 138proc_GetDeletedGrants
139proc_GetDeletedInfoReleases 140proc_GetDeletedIntakes 141proc_GetDeletedInterventions
142proc_GetDeletedNotes 143proc_GetDeletedParticipantFiles 144proc_GetDeletedParticipants
145proc_GetDeletedPresentations 146proc_GetDeletedQuestionnaires 147proc_GetDeletedReferrals
148proc_GetDeletedReportNarratives 149proc_GetDeletedServiceSessions 150proc_GetDeletedStaff
151proc_GetDeletedSurveys 152proc_GetDeletedTrainingSessions 153proc_GetDeletedVolunteerActivities
154proc_GetDelinquentData 155proc_GetEmerContact 156proc_GetGrant
157proc_GetGrantorLists 158proc_GetInfoRelease 159proc_GetInfoReleaseLookups
160proc_GetInfoReleases 161proc_GetIntake 162proc_GetIntakeQuestionnaires
163proc_GetIntakeServices 164proc_GetIntakeServicesAndReferrals 165proc_GetIntervention
166proc_GetInterventionLists 167proc_GetInterventions 168proc_GetLookupsNormal
169proc_GetLookupsOther 170proc_GetNote 171proc_GetNotes
172proc_GetNotesIndividual 173proc_GetOrganizationData 174proc_GetOriginIntakeData
175proc_GetOtherMergeCategories 176proc_GetParticipantComplete 177proc_GetParticipantFile
178proc_GetParticipantFileInfo 179proc_GetParticipantLists 180proc_GetPhases
181proc_GetPresentation 182proc_GetPresentationLists 183proc_GetPresentations
184proc_GetPrompts 185proc_GetQuestionnaire 186proc_GetQuestionnaires
187proc_GetReferral 188proc_GetReferrals 189proc_GetReportLists
190proc_GetReportNarrative 191proc_GetReportNarratives 192proc_GetRevisionNumber
193proc_GetRoom 194proc_GetRoomBedAssignment 195proc_GetServiceSession
196proc_GetServiceSessions 197proc_GetServicesLists 198proc_GetServicesProgramsFocuses
199proc_GetServicesProgramsFocusesGoods 200proc_GetShelter 201proc_GetShelterBeds
202proc_GetShelterCollections 203proc_GetShelters 204proc_GetStaffMember
205proc_GetStaffMemberExt 206proc_GetStaffMembers 207proc_GetStaffMembersExt
208proc_GetStaffReferrals 209proc_GetStaffRequirements 210proc_GetStaffTrainingRequirements
211proc_GetSurvey 212proc_GetSurveyLists 213proc_GetSurveyResults
214proc_GetSurveys 215proc_GetTANFvalues 216proc_GetTaskAndPhaseStatus
217proc_GetTasks 218proc_GetTrainingLists 219proc_GetTrainingSession
220proc_GetTrainingSessions 221proc_GetUnlinkedIntakeCalls 222proc_GetUnlinkedIntakes
223proc_GetVolunteerActivities 224proc_GetVolunteerActivity 225proc_GetVolunteers
226proc_InsertAbuser 227proc_InsertAlias 228proc_InsertBed
229proc_InsertCallService 230proc_InsertCampus 231proc_InsertChild
232proc_InsertChildAbsence 233proc_InsertChildAlias 234proc_InsertClientSession
235proc_InsertCredential 236proc_InsertEmerContact 237proc_InsertFocus
238proc_InsertFocusService 239proc_InsertGoal 240proc_InsertGrant
241proc_InsertGrantSurveys 242proc_InsertGrantTarget 243proc_InsertHotlineReferral
244proc_InsertIntakeBed 245proc_InsertIntakePhase 246proc_InsertIntakeStaff
247proc_InsertIntakeTask 248proc_InsertIntakeVictimType 249proc_InsertNarrativeResponse
250proc_InsertNote 251proc_InsertParticipantFile 252proc_InsertPet
253proc_InsertPresentationTopic 254proc_InsertProgram 255proc_InsertProgramService
256proc_InsertQuestionnaire 257proc_InsertQuestionResponses 258proc_InsertReferral
259proc_InsertReleaseEntity 260proc_InsertRHBA 261proc_InsertRoom
262proc_InsertRoomBedAssignment 263proc_InsertSessionNote 264proc_InsertShelter
265proc_InsertStaffCallService 266proc_InsertStaffMember 267proc_InsertStaffMemberExt
268proc_InsertStaffPresentation 269proc_InsertStaffReferral 270proc_InsertStaffRequirement
271proc_InsertStaffSession 272proc_InsertStaffTraining 273proc_InsertSurvey
274proc_InsertSurveyNarrative 275proc_InsertSurveyQuestions 276proc_InsertTangibleGoods
277proc_InsertTopic 278proc_InsertTrip 279proc_InsertVolunteer
280proc_LinkIntakes 281proc_LinkIntakeToCall 282proc_LookupAddNewEntry
283proc_LookupAddOtherEntry 284proc_MapService 285proc_MergeAbuserRelationship
286proc_MergeCallSubject 287proc_MergeCampus 288proc_MergeChildren
289proc_MergeCredential 290proc_MergeEthnicity 291proc_MergeExitDestination
292proc_MergeExitHousing 293proc_MergeExitReason 294proc_MergeFacilitator
295proc_MergeFocus 296proc_MergeGoodType 297proc_MergeHotlineReferral
298proc_MergeLanguage 299proc_MergeLawAgency 300proc_MergeLocation
301proc_MergeParticipants 302proc_MergePriorResidence 303proc_MergeProgram
304proc_MergeReasonDenied 305proc_MergeReferralSource 306proc_MergeReferralType
307proc_MergeReleaseEntity 308proc_MergeReleaseType 309proc_MergeReligion
310proc_MergeService 311proc_MergeServiceLocation 312proc_MergeShelter
313proc_MergeTopic 314proc_MergeTribe 315proc_MergeTripPurpose
316proc_MergeVehicle 317proc_RebuildIndexes 318proc_RestoreAbuser
319proc_RestoreAbuserAlert 320proc_RestoreAbuserIntake 321proc_RestoreAlias
322proc_RestoreAssessment 323proc_RestoreCall 324proc_RestoreChild
325proc_RestoreChildAlias 326proc_RestoreChildIntake 327proc_RestoreClientSession
328proc_RestoreCommunityMember 329proc_RestoreCredential 330proc_RestoreEmergencyContact
331proc_RestoreGrant 332proc_RestoreGrantor 333proc_RestoreInfoRelease
334proc_RestoreIntake 335proc_RestoreIntakeBedAssignment 336proc_RestoreIntervention
337proc_RestoreNote 338proc_RestoreParticipant 339proc_RestoreParticipantFile
340proc_RestorePresentation 341proc_RestoreQuestionnaire 342proc_RestoreReferral
343proc_RestoreReportNarrative 344proc_RestoreServiceSession 345proc_RestoreStaffMember
346proc_RestoreSurvey 347proc_RestoreTrainingSession 348proc_RestoreVolunteerActivity
349proc_SaveAbuserAlert 350proc_SaveAbuserIntake 351proc_SaveAssessment
352proc_SaveAssessmentItem 353proc_SaveBackupSettings 354proc_SaveCall
355proc_SaveChildIntake 356proc_SaveCommunityMember 357proc_SaveEntry
358proc_SaveGrantor 359proc_SaveGrantorService 360proc_SaveInfoRelease
361proc_SaveIntakePhase 362proc_SaveIntakeTask 363proc_SaveIntervention
364proc_SaveNewChildIntake 365proc_SaveNewIntake 366proc_SaveOrganizationData
367proc_SaveParticipant 368proc_SavePhase 369proc_SavePresentation
370proc_SaveQuestion 371proc_SaveReportNarrative 372proc_SaveService
373proc_SaveServiceSession 374proc_SaveTanfValues 375proc_SaveTangibleGoodType
376proc_SaveTask 377proc_SaveTrainingSession 378proc_SaveVolunteerActivity
379proc_SearchCalls 380proc_SearchDOB 381proc_SearchEntryDates
382proc_SearchExitDates 383proc_SearchNamesExact 384proc_SearchNamesLike
385proc_SearchOptionalID 386proc_SearchSSNExact 387proc_SearchSSNLike
388proc_UnlinkIntakes 389proc_UnmapService 390proc_UpdateAbuser
391proc_UpdateAlias 392proc_UpdateBed 393proc_UpdateCampus
394proc_UpdateChild 395proc_UpdateChildAlias 396proc_UpdateCredential
397proc_UpdateEmerContact 398proc_UpdateFocus 399proc_UpdateGrant
400proc_UpdateIntake 401proc_UpdateIntakeBed 402proc_UpdateNote
403proc_UpdateProgram 404proc_UpdatePrompts 405proc_UpdateQuestionnaire
406proc_UpdateReferral 407proc_UpdateRoom 408proc_UpdateRoomBedAssignment
409proc_UpdateShelter 410proc_UpdateStaffMember 411proc_UpdateStaffMemberExt
412proc_UpdateStaffRequirement 413proc_UpdateSurvey 414proc_UpdateTopic
415rpt_AbuserServices 416rpt_AbuserStatus 417rpt_ACJC
418rpt_Assessments 419rpt_BatteredImmigrantWomen 420rpt_BedAssignments
421rpt_BedAssignments2 422rpt_ClientSummary 423rpt_CompareSurveys
424rpt_Demographics 425rpt_DesInterventionPerformanceMeasures 426rpt_DESoutcomes
427rpt_DirectorsReport 428rpt_DVLAP 429rpt_DVLAPinvoice
430rpt_DVSR 431rpt_DVSRdetails 432rpt_ExitData
433rpt_FVPSA 434rpt_FVPSAquarterly 435rpt_GenericReport
436rpt_HotlineCallSummary 437rpt_HUD 438rpt_InformationRelease
439rpt_IntakeData 440rpt_LocationsServed 441rpt_NavajoNation
442rpt_NewClients 443rpt_ParticipantRoster 444rpt_PermanentSafeHousing
445rpt_PetRoster 446rpt_PhaseStatus 447rpt_ReferralAgencies
448rpt_ReferralsByStaff 449rpt_ReferralsByType 450rpt_ReferralSources
451rpt_RepeatParticipants 452rpt_ResidentCountByDay 453rpt_RhbaParticipants
454rpt_RhbaServices 455rpt_RSHN 456rpt_RSHNspreadsheet
457rpt_ServiceAndFocus 458rpt_ServiceFocusSummary 459rpt_ServiceLocations
460rpt_ServicesByClient 461rpt_ServicesByProgram 462rpt_ServicesByStaff
463rpt_ServicesByType 464rpt_ServicesSummary 465rpt_StaffAdvocates
466rpt_StaffMemberTraining 467rpt_StaffPresentations 468rpt_StaffRequirements
469rpt_StaffRoster 470rpt_StaffServicesToClients 471rpt_STOP
472rpt_STOPsa 473rpt_SurveyReportData 474rpt_TangibleGoods
475rpt_TaskStatus 476rpt_TrainingSessions 477rpt_TripLog
478rpt_VictimsServed 479rpt_VOCA 480rpt_VolunteerActivities
481rpt_ZipCodesServed   >   

proc_AddStaffRequirement
CREATE PROCEDURE dbo.proc_AddStaffRequirement
	(@StaffID INT, @RequirementID INT)
	AS
	IF (SELECT StaffID FROM StaffRequirements WHERE StaffID = @StaffID AND RequirementID = @RequirementID) IS NULL
		BEGIN
			INSERT INTO StaffRequirements (StaffID, RequirementID) VALUES (@StaffID, @RequirementID)
		END

proc_AllAbusers
CREATE PROCEDURE dbo.proc_AllAbusers 
	AS  
	SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName  
	FROM Abusers  
	WHERE DeletedDate IS NULL  
	ORDER BY LastName, FirstName, MI, DOB  

proc_AllChildren
CREATE PROCEDURE dbo.proc_AllChildren 
	AS  
	SELECT ParticipantID, ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName  
	FROM Children  
	WHERE DeletedDate IS NULL
	UNION
	SELECT c.ParticipantID, ca.ChildID, ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName
	FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID
	WHERE ca.DeletedDate IS NULL AND c.DeletedDate IS NULL
	ORDER BY FullName

proc_AllParticipants
CREATE PROCEDURE dbo.proc_AllParticipants 
	AS 
	SELECT ParticipantID, OptionalIdentifier, FullName = CASE
		WHEN ReturnStatusID = 1 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [A]'
		WHEN ReturnStatusID = 2 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [B]'
		WHEN ReturnStatusID = 3 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [C]'
		WHEN ReturnStatusID = 4 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [D]'
		END
	FROM Participants 
	WHERE DeletedDate IS NULL
	UNION
	SELECT a.ParticipantID, OptionalIdentifier, FullName = CASE
		WHEN ReturnStatusID = 1 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [A]' 
		WHEN ReturnStatusID = 2 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [B]'
		WHEN ReturnStatusID = 3 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [C]'
		WHEN ReturnStatusID = 4 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [D]'
		END
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID 
	WHERE a.DeletedDate IS NULL And p.DeletedDate IS NULL
	ORDER BY FullName

proc_AlterLoginSysAdmin
CREATE PROCEDURE dbo.proc_AlterLoginSysAdmin	-- Procedure when SysAdmin is changing user's login
	(@MustChange BIT, @Password NVARCHAR(128), @PasswordChanged BIT, 
	 @UserName SYSNAME, @OldRole VARCHAR(50), @NewRole VARCHAR(50))
	AS
	DECLARE @SQL NVARCHAR(4000);
	IF @OldRole <> @NewRole
		BEGIN
			IF @OldRole = 'sysadmin'
				BEGIN
					EXECUTE sp_dropsrvrolemember @loginame = @UserName, @rolename = @OldRole;
					EXECUTE sp_grantdbaccess @name_in_db = @UserName, @loginame = @UserName;
					EXECUTE sp_addrolemember @membername = @UserName, @rolename = @NewRole;
				END
			ELSE IF @NewRole = 'sysadmin'
				BEGIN
					EXECUTE sp_droprolemember @membername = @UserName, @rolename = @OldRole;
					EXECUTE sp_dropuser @name_in_db = @UserName;
					EXECUTE sp_addsrvrolemember @loginame = @UserName, @rolename = @NewRole;
				END
			ELSE
				BEGIN
					EXECUTE sp_droprolemember @membername = @UserName, @rolename = @OldRole;
					EXECUTE sp_addrolemember @membername = @UserName, @rolename = @NewRole;
				END
		END
	IF @PasswordChanged = 1 And @MustChange = 0
		BEGIN
			SET @SQL = 'ALTER LOGIN ' + QUOTENAME(@UserName) + ' WITH PASSWORD = ''' + REPLACE(@password, '''', '''''') + '''';
			EXECUTE(@SQL);
		END
	IF @PasswordChanged = 1 And @MustChange = 1
		BEGIN
			SET @SQL = 'ALTER LOGIN ' + QUOTENAME(@UserName) + ' WITH PASSWORD = ''' + REPLACE(@password, '''', '''''') + '''' + ', MUST_CHANGE';
			EXECUTE(@SQL);
		END
	IF @PasswordChanged = 0 And @MustChange = 1
		BEGIN
			SET @SQL = 'ALTER LOGIN ' + QUOTENAME(@UserName) + ' WITH CHECK_EXPIRATION = ON, CHECK_POLICY = ON, MUST_CHANGE';
			EXECUTE(@SQL);
		END

proc_AuditRecords
CREATE PROCEDURE dbo.proc_AuditRecords
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME)
	AS
	-- Services outside associated intake period
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE SessionDate BETWEEN @StartDate AND @EndDate 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND SessionDate NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
		INNER JOIN Children c ON ci.ChildID = c.ChildID
	WHERE SessionDate BETWEEN @StartDate AND @EndDate 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND SessionDate NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 3, ClientType = 'Abuser', LastName + ', ' + FirstName + ' ' + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID AND cs.ClientTypeID = 3
		INNER JOIN Abusers a ON ai.AbuserID = a.AbuserID
	WHERE SessionDate BETWEEN @StartDate AND @EndDate 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND	SessionDate NOT BETWEEN ai.EntryDate AND ISNULL(ai.ExitDate, '6/1/2079')
	ORDER BY ClientTypeID, ClientName, SessionDate;	
	-- Services NOT linked to intake (IntakeID = 0) that are within an intake period
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Participants p ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
	WHERE SessionDate BETWEEN @StartDate AND @EndDate AND cs.IntakeID = 0 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND ParticipantID IN
		(SELECT ParticipantID FROM Intakes 
		WHERE DeletedDate IS NULL AND s.SessionDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Children c ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
	WHERE SessionDate BETWEEN @StartDate AND @EndDate AND cs.IntakeID = 0 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND ChildID IN
		(SELECT ChildID FROM ChildIntakes 
		WHERE DeletedDate IS NULL AND s.SessionDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	UNION ALL
	SELECT ClientTypeID = 3, ClientType = 'Abuser', LastName + ', ' + FirstName + MI AS ClientName, s.SessionID AS ID, SessionDate AS EventDate, ServiceName AS EventType
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Abusers a ON a.AbuserID = cs.ClientID AND cs.ClientTypeID = 3
	WHERE SessionDate BETWEEN @StartDate AND @EndDate AND cs.IntakeID = 0 
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		AND AbuserID IN
		(SELECT AbuserID FROM AbuserIntakes 
		WHERE DeletedDate IS NULL AND s.SessionDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	ORDER BY ClientTypeID, ClientName, SessionDate;	
	-- Referrals linked to intakes that are outside intake period
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN Intakes i ON r.IntakeID = i.IntakeID AND r.ClientTypeID = 1
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.DeletedDate IS NULL AND
		ReferralDate NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN ChildIntakes ci ON r.IntakeID = ci.ChildIntakeID AND r.ClientTypeID = 2
		INNER JOIN Children c ON c.ChildID = ci.ChildID
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.DeletedDate IS NULL AND
		ReferralDate NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 3, ClientType = 'Abuser', LastName + ', ' + FirstName +  ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN AbuserIntakes ai ON r.IntakeID = ai.AbuserIntakeID AND r.ClientTypeID = 3
		INNER JOIN Abusers a ON ai.AbuserID = a.AbuserID
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.DeletedDate IS NULL AND
		ReferralDate NOT BETWEEN ai.EntryDate AND ISNULL(ai.ExitDate, '6/1/2079')
	ORDER BY ClientTypeID, ClientName, ReferralDate;
	-- Referrals NOT linked to intakes (IntakeID = 0) that are within an intake period.
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN Participants p ON r.ClientID = p.ParticipantID AND r.ClientTypeID = 1
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.IntakeID = 0 AND ParticipantID IN
		(SELECT ParticipantID FROM Intakes
		WHERE DeletedDate IS NULL AND r.ReferralDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN Children c ON r.ClientID = c.ChildID AND r.ClientTypeID = 2
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.IntakeID = 0 AND ChildID IN
		(SELECT ChildID FROM ChildIntakes
		WHERE DeletedDate IS NULL AND r.ReferralDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	UNION ALL
	SELECT ClientTypeID = 3, ClientType = 'Abuser', LastName + ', ' + FirstName + ' ' + MI AS ClientName, r.ReferralID AS ID, ReferralDate AS EventDate, ReferralType AS EventType
	FROM xReferralType x INNER JOIN Referrals r ON r.ReferralTypeID = x.ReferralTypeID
		INNER JOIN Abusers a ON r.ClientID = a.AbuserID AND r.ClientTypeID = 3
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate AND r.IntakeID = 0 AND a.AbuserID IN
		(SELECT AbuserID FROM AbuserIntakes
		WHERE DeletedDate IS NULL AND r.ReferralDate BETWEEN EntryDate AND ISNULL(ExitDate, '6/1/2079'))
	ORDER BY ClientTypeID, ClientName, R
eferralDate;	
	-- Invalid 'Continuation Intakes'
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, IntakeType AS EventType
	FROM xIntakeType x INNER JOIN Intakes i ON i.IntakeTypeID = x.IntakeTypeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
		LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
	WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND i.IsContinuation = 1 AND i.DeletedDate IS NULL AND li.OriginIntakeID IS NULL
	ORDER BY ClientName;
	-- Child Absences outside of intake period
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, ci.IntakeID AS ID, ca.DateOut AS EventDate, 'Child Absence' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
	WHERE  ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		AND ca.DateOut NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
		AND ci.DeletedDate IS NULL
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, ci.IntakeID AS ID, ca.DateOut AS EventDate, 'Child Absence' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
	WHERE  ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		AND ci.DeletedDate IS NULL
		AND ca.DateReturn  NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
	ORDER BY ClientName;
	-- Crisis/Non-Resident/Transitional intake not in Crisis/Transitional shelter
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, EntryDate AS EventDate, IntakeType AS EventType
	FROM xIntakeType x INNER JOIN Intakes i ON i.IntakeTypeID = x.IntakeTypeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND ((i.IntakeTypeID = 1 AND (ShelterTypeID <> 1 OR Residential = 0))
			OR (i.IntakeTypeID = 4 AND (ShelterTypeID <> 1 OR NonResidential = 0)) 
			OR (i.IntakeTypeID = 2 AND ShelterTypeID <> 2))
	ORDER BY ClientName;
	-- Intake bed assignment outside intake period
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, DateIn AS EventDate, 'Bed Assignment' AS EventType
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeBeds ib ON i.IntakeID = ib.IntakeID AND ib.ClientTypeID = 1
	WHERE i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND ib.DeletedDate IS NULL AND 
		((i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)) 
			OR ib.DateIn BETWEEN @StartDAte AND @EndDate OR ib.DateOut BETWEEN @StartDate AND @EndDate)
		AND ib.DateIn NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, DateOut AS EventDate, 'Bed Assignment' AS EventType
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeBeds ib ON i.IntakeID = ib.IntakeID AND ib.ClientTypeID = 1
	WHERE i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND ib.DeletedDate IS NULL AND
		 i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND ib.DateOut IS NOT NULL AND ib.DateOut NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, ci.IntakeID AS ID, DateIn AS EventDate, 'Bed Assignment' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN IntakeBeds ib ON ci.ChildIntakeID = ib.IntakeID AND ib.ClientTypeID = 2
	WHERE ci.DeletedDate IS NULL AND c.DeletedDate IS NULL AND ib.DeletedDate IS NULL AND
		ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate) 
		AND ib.DateIn NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, ci.IntakeID AS ID, DateOut AS EventDate, 'Bed Assignment' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN IntakeBeds ib ON ci.ChildIntakeID = ib.IntakeID AND ib.ClientTypeID = 2
	WHERE ci.DeletedDate IS NULL AND c.DeletedDate IS NULL AND ib.DeletedDate IS NULL AND
		ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate) 
		AND ib.DateOut IS NOT NULL AND ib.DateOut NOT BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/1/2079')
	ORDER BY ClientTypeID, ClientName;
	-- Child Entry/Exit dates outside parent's
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, ci.EntryDate AS EventDate, 'Child Intake' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
	WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND ci.EntryDate NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
		AND ci.DeletedDate IS NULL
	UNION ALL
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, ci.ExitDate AS EventDate, 'Child Intake' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
	WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND ci.ExitDate IS NOT NULL AND ci.DeletedDate IS NULL
		AND ci.ExitDate NOT BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
	ORDER BY ClientName;
	-- Parent has exit date but child does not
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, ci.EntryDate AS EventDate, 'Child Intake' AS EventType
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
	WHERE ci.EntryDate <= @EndDate AND ci.DeletedDate IS NULL AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate) AND i.DeletedDate IS NULL
		AND ci.ExitDate IS NULL AND i.ExitDate IS NOT NULL AND ci.DeletedDate IS NULL
	ORDER BY ClientName;
	-- Intakes where linked call not "Shelter Provided ..."
	SELECT ClientTypeID = 1, ClientType = 'Participant', p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake Call' AS EventType
	FROM Participants p INNER JOIN Intakes i ON i.ParticipantID = p.ParticipantID
		INNER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
		INNER JOIN ShelterRequests sr ON ic.CallID = sr.CallID
	WHERE i.DeletedDate IS NULL AND i.EntryDate BETWEEN @StartDate AND @EndDate 
		AND sr.RequestOutcomeID NOT IN (2, 3);
	-- Intakes where entrydate is less than linked call date
	SELECT ClientTypeID = 1, ClientType = 'Participant', p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake Call' AS EventType
	FROM Participants p INNER JOIN Intakes i ON i.ParticipantID = p.ParticipantID
		INNER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
		INNER JOIN Calls c ON ic.CallID = c.CallID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate < c.CallDate AND i.EntryDate BETW
EEN @StartDate AND @EndDate
	ORDER BY ClientName;
	-- Overlapping intakes
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI as ClientName, p.ParticipantID AS ID,	i.EntryDate AS EventDate, 'Overlapping Intake' AS EventType
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN Intakes i2 ON i.ParticipantID = i2.ParticipantID
	WHERE i.IntakeID <> i2.IntakeID AND i.DeletedDate IS NULL AND i2.DeletedDate IS NULL
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND i.EntryDate BETWEEN i2.EntryDate AND DateAdd(day, -1, ISNULL(i2.ExitDate, '6/1/2079'))
	ORDER BY ClientName;
	-- VictimType is not specified for Crisis/NonResident/Transitional intake
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake' AS EventType
	FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND i.IntakeTypeID IN (1, 2, 4) 
		AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL 
		AND  (SELECT TOP 1 VictimTypeID FROM IntakeVictimType WHERE IntakeID = i.IntakeID) IS NULL
	ORDER BY ClientName;
	-- Substance abuse is unknown
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake' AS EventType
	FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND i.IntakeTypeID IN (1, 2, 4) AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND
		i.SubstanceAbuseID IS NULL
	ORDER BY ClientName;
	-- Participant/child ethnicity is Unknown
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, p.ParticipantID AS ID, i.EntryDate AS EventDate, 'Unknown Ethnicity' AS EventType
	FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate) AND i.IntakeTypeID IN (1, 2, 4) 
		AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.EthnicityID = 1
	UNION
	SELECT ClientTypeID = 2, ClientType = 'Child', LastName + ', ' + FirstName + ' ' + MI AS ClientName, c.ParticipantID AS ID, ci.EntryDate AS EventDate, 'Unknown Ethnicity' AS EventType
	FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
	WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.EntryDate >= @StartDate) AND i.IntakeTypeID IN (1, 2, 4)
		AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND c.EthnicityID = 1
	ORDER BY ClientTypeID, ClientName;
	-- Unknown demographic information:  Marital status and Citizenship
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake' AS EventType
	FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND i.IntakeTypeID IN (1, 2, 4) 
		AND (MaritalStatusID = 0 OR CitizenshipID = 1) AND
		p.DeletedDate IS NULL AND i.DeletedDate IS NULL
	ORDER BY ClientName;
	-- Abuser relationship is not specified for Crisis/NonResident/Transitional intake
	SELECT ClientTypeID = 1, ClientType = 'Participant', LastName + ', ' + FirstName + ' ' + MI AS ClientName, i.IntakeID AS ID, i.EntryDate AS EventDate, 'Intake' AS EventType
	FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND i.IntakeTypeID IN (1, 2, 4) 
		AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL 
		AND (i.AbuserRelationshipID IS NULL OR i.AbuserRelationshipID = 1) 
	ORDER BY ClientName;

proc_ChangeCallToNoShow
CREATE PROCEDURE dbo.proc_ChangeCallToNoShow
	(@CallID INT, @UserName VARCHAR(50))
	AS
	UPDATE ShelterRequests SET RequestOutcomeID = 7 WHERE CallID = @CallID
	UPDATE Calls SET ModifiedBy = @UserName, ModifiedDate = getdate() WHERE CallID = @CallID
	RETURN

proc_CurrentAbusers
CREATE PROCEDURE dbo.proc_CurrentAbusers  
	AS  
	SELECT Abusers.AbuserID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')' AS FullName  
	FROM Abusers INNER JOIN AbuserIntakes ON Abusers.AbuserID = AbuserIntakes.AbuserID  
	WHERE (Abusers.DeletedDate IS NULL) AND (AbuserIntakes.DeletedDate IS NULL) AND (AbuserIntakes.ExitDate IS NULL)  
	ORDER BY LastName, FirstName, MI, DOB 

proc_CurrentChildren
CREATE PROCEDURE dbo.proc_CurrentChildren 
	AS  
	SELECT c.ParticipantID, c.ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')' AS FullName, IntakeID  
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID  
	WHERE (c.DeletedDate IS NULL) AND (ci.DeletedDate IS NULL) AND (ci.ExitDate IS NULL)
	UNION
	SELECT c.ParticipantID, ca.ChildID, ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI + ' (' + CONVERT(VarChar(50), DOB, 110) + ')' AS FullName, IntakeID
	FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID
		INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID 
	WHERE ca.DeletedDate IS NULL AND c.DeletedDate IS NULL AND ci.ExitDate IS NULL
	ORDER BY FullName

proc_CurrentParticipants
CREATE PROCEDURE dbo.proc_CurrentParticipants  
	AS  
	SELECT Participants.ParticipantID, IntakeID, OptionalIdentifier, FullName = CASE
		WHEN ReturnStatusID = 1 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [A]'  
		WHEN ReturnStatusID = 2 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [B]'  
		WHEN ReturnStatusID = 3 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [C]'  
		WHEN ReturnStatusID = 4 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [D]'  
		END
	FROM Participants INNER JOIN Intakes ON Participants.ParticipantID = Intakes.ParticipantID  
	WHERE (Participants.DeletedDate IS NULL) AND (Intakes.DeletedDate IS NULL) AND (Intakes.ExitDate IS NULL)
	UNION
	SELECT a.ParticipantID, IntakeID, OptionalIdentifier, FullName = CASE
		WHEN ReturnStatusID = 1 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [A]'  
		WHEN ReturnStatusID = 2 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [B]'  
		WHEN ReturnStatusID = 3 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [C]'  
		WHEN ReturnStatusID = 4 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [D]'   
		END
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
		INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
	WHERE a.DeletedDate IS NULL AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL and i.ExitDate IS NULL
	ORDER BY FullName

proc_DeleteAbuser
CREATE PROCEDURE dbo.proc_DeleteAbuser
	(@AbuserID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME
	SET @GetDate = GETDATE()
	UPDATE Abusers SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE AbuserID = @AbuserID And DeletedDate IS Null
	UPDATE AbuserIntakes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE AbuserID = @AbuserID AND DeletedDate IS NULL
	UPDATE Notes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @AbuserID AND ClientTypeID = 3 AND DeletedDate IS NULL
	UPDATE ClientSessions Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @AbuserID And ClientTypeID = 3 AND DeletedDate IS NULL
	UPDATE Referrals Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @AbuserID And ClientTypeID = 3 AND DeletedDate IS NULL
	UPDATE Questionnaires SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE DeletedDate IS NULL AND ClientTypeID = 3 AND IntakeID IN
			(SELECT AbuserIntakeID FROM AbuserIntakes WHERE AbuserID = @AbuserID)

proc_DeleteAbuserAlert
CREATE PROCEDURE dbo.proc_DeleteAbuserAlert
	(@AlertID INT, @UserName VARCHAR(50))
	AS
	UPDATE AbuserAlerts
	SET DeletedDate = getdate(), DeletedBy = @UserName
	WHERE AlertID = @AlertID
	RETURN

proc_DeleteAbuserIntake
CREATE PROCEDURE dbo.proc_DeleteAbuserIntake
	(@AbuserIntakeID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME SET @GetDate = getdate()
	UPDATE AbuserIntakes SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE AbuserIntakeID = @AbuserIntakeID
	UPDATE Referrals SET  DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID = @AbuserIntakeID AND ClientTypeID = 3 AND DeletedDate IS NULL
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID = @AbuserIntakeID AND ClientTypeID = 3 AND DeletedDate IS NULL
	UPDATE Questionnaires SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE IntakeID = @AbuserIntakeID AND ClientTypeID = 3 AND DeletedDate IS NULL

proc_DeleteAlias
CREATE PROCEDURE dbo.proc_DeleteAlias
	(@AliasID INT, @UserName VARCHAR(50))
	AS
	UPDATE Aliases
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE AliasID = @AliasID AND DeletedDate IS NULL
	RETURN

proc_DeleteAssessment
CREATE PROCEDURE dbo.proc_DeleteAssessment
	(@AssessmentID INT, @UserName VARCHAR(50))
	AS
	UPDATE Assessments
	SET DeletedBy = @UserName, DeletedDate = GETDATE()
	WHERE AssessmentID = @AssessmentID AND DeletedDate IS NULL

proc_DeleteCall
CREATE PROCEDURE dbo.proc_DeleteCall  
	(@CallID INT, @UserName VARCHAR(50))  
	AS  
	UPDATE Calls  
	Set DeletedBy = @UserName, DeletedDate = getdate()  
	WHERE CallID = @CallID  
	RETURN

proc_DeleteChild
CREATE PROCEDURE dbo.proc_DeleteChild
	(@ChildID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME
	SET @GetDate = getdate()
	UPDATE Children SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE ChildID = @ChildID
	UPDATE Notes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ChildID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE ChildIntakes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ChildID = @ChildID AND DeletedDate IS NULL
	UPDATE Referrals SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ChildID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ChildID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE IntakeBeds SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE DeletedDate IS NULL AND ClientTypeID = 2 And IntakeID In
		(SELECT IntakeID FROM ChildIntakes WHERE ChildID = @ChildID)

proc_DeleteChildAlias

CREATE PROCEDURE dbo.proc_DeleteChildAlias
	(@AliasID INT, @UserName VARCHAR(50))
	AS
	UPDATE ChildAliases
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE AliasID = @AliasID AND DeletedDate IS NULL

proc_DeleteChildIntake
CREATE PROCEDURE dbo.proc_DeleteChildIntake
	(@ChildIntakeID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME SET @GetDate = getdate()
	UPDATE ChildIntakes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ChildIntakeID = @ChildIntakeID
	UPDATE Referrals SET  DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID = @ChildIntakeID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE IntakeBeds SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID = @ChildIntakeID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID = @ChildIntakeID AND ClientTypeID = 2 AND DeletedDate IS NULL
	UPDATE Questionnaires SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE IntakeID = @ChildIntakeID AND ClientTypeID = 2 AND DeletedDate IS NULL

proc_DeleteClientSession
CREATE PROCEDURE dbo.proc_DeleteClientSession
	(@SessionID INT, @ClientID INT, @ClientTypeID INT, @UserName VARCHAR(50))
	AS
	DECLARE @SessionRecords INT
	SET @SessionRecords =
		(SELECT Count(*) FROM ClientSessions WHERE SessionID = @SessionID And DeletedDate Is Null)
	UPDATE ClientSessions
	SET DeletedDate = getdate(), DeletedBy = @UserName
	WHERE SessionID = @SessionID And ClientID = @ClientID And ClientTypeID = @ClientTypeID
	IF @SessionRecords = 1
			UPDATE Sessions
			SET DeletedDate = getdate(), DeletedBy = @UserName
			WHERE SessionID = @SessionID
			UPDATE StaffSessions
			SET DeletedDate = getdate(), DeletedBy = @UserName
			WHERE SessionID = @SessionID
	RETURN

proc_DeleteCommunityMember
CREATE PROCEDURE dbo.proc_DeleteCommunityMember
	(@MemberID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME
	SET @GetDate = getdate()
	UPDATE CommunityMembers SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE MemberID = @MemberID
	UPDATE Notes SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @MemberID AND ClientTypeID = 4 AND DeletedDate IS NULL
	UPDATE Referrals SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @MemberID AND ClientTypeID = 4 AND DeletedDate IS NULL
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @MemberID AND ClientTypeID = 4 AND DeletedDate IS NULL
	UPDATE Interventions SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE ClientID = @MemberID AND ClientTypeID = 4 AND DeletedDate IS NULL

proc_DeleteCredential
CREATE PROCEDURE dbo.proc_DeleteCredential
	(@CredentialID INT, @UserName VARCHAR(50))
	AS
	UPDATE Credentials
		Set DeletedDate = getdate(), DeletedBy = @UserName
	WHERE CredentialID = @CredentialID
	RETURN

proc_DeleteEmerContact
CREATE PROCEDURE dbo.proc_DeleteEmerContact
	(@EmerContactID INT, @UserName VARCHAR(50))
	AS
	UPDATE EmerContacts
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE EmerContactID = @EmerContactID AND DeletedDate IS NULL
	RETURN

proc_DeleteFocus
CREATE PROCEDURE dbo.proc_DeleteFocus
	(@FocusID INT, @Success BIT OUTPUT)
	AS
	DELETE FROM Focus WHERE FocusID = @FocusID
	SET @Success = CASE WHEN @@ERROR = 0 THEN 1 ELSE 0 END

proc_DeleteGrant
CREATE PROCEDURE dbo.proc_DeleteGrant
	(@GrantID INT, @UserName VARCHAR(50))
	AS
	UPDATE Grants
	SET DeletedDate = getdate(), DeletedBy = @UserName
	WHERE GrantID = @GrantID
	RETURN

proc_DeleteGrantor
CREATE PROCEDURE dbo.proc_DeleteGrantor
	(@GrantorID INT, @UserName VARCHAR(50))
	AS
	UPDATE Grantors Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE GrantorID = @GrantorID AND DeletedDate IS NULL
	UPDATE Grants SET DeletedBy = @UserName, DeletedDate = GETDATE()
	WHERE GrantorID = @GrantorID AND DeletedDate IS NULL
	UPDATE GrantorServices SET DeletedBy = @UserName, DeletedDate = GETDATE()
	WHERE GrantorID = @GrantorID AND DeletedDate IS NULL
	UPDATE ServiceMap SET DeletedBy = @UserName, DeletedDate = GETDATE()
	WHERE GrantorID = @GrantorID AND DeletedDate IS NULL

proc_DeleteInfoRelease
CREATE PROCEDURE dbo.proc_DeleteInfoRelease
	(@ReleaseID INT, @UserName VARCHAR(50))
	AS
	UPDATE InfoReleases
	SET DeletedBy = @UserName, DeletedDate = GETDATE()
	WHERE ReleaseID = @ReleaseID AND DeletedDate IS NULL

proc_DeleteIntakeCall
CREATE PROCEDURE dbo.proc_DeleteIntakeCall
	(@IntakeID INT, @CallID INT)
	AS
	DELETE FROM IntakeCalls WHERE IntakeID = @IntakeID AND CallID = @CallID

proc_DeleteIntervention
CREATE PROCEDURE dbo.proc_DeleteIntervention
	(@InterventionID INT, @UserName VARCHAR(50))
	AS
	DECLARE @SessionID INT, @GetDate DATETIME
	SET @GetDate = GETDATE()
	SELECT @SessionID = 
		(SELECT TOP 1 SessionID 
		FROM Interventions
		WHERE InterventionID = @InterventionID)
	UPDATE Interventions 
	SET DeletedDate = @GetDate, DeletedBy = @UserName
	WHERE InterventionID = @InterventionID
	UPDATE Sessions
	SET DeletedDate = @GetDate, DeletedBy = @UserName
	WHERE SessionID = @SessionID

proc_DeleteNote
CREATE PROCEDURE dbo.proc_DeleteNote
	(@NoteID INT, @UserName VARCHAR(50))
	AS
	UPDATE Notes
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE NoteID = @NoteID AND DeletedDate IS NULL
	RETURN

proc_DeleteParticipant
CREATE PROCEDURE dbo.proc_DeleteParticipant
	(@ParticipantID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME
	SET @GetDate = getdate()
	UPDATE Interventions SET DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE ClientID = @ParticipantID AND ClientTypeID = 1	
	UPDATE Participants Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ParticipantID = @ParticipantID
	UPDATE Intakes Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL 
	UPDATE EmerContacts Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL
	UPDATE Children Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL
	UPDATE Referrals Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ParticipantID And ClientTypeID = 1 AND DeletedDate IS NULL
	UPDATE ClientSessions Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ParticipantID And ClientTypeID = 1 AND DeletedDate IS NULL
	UPDATE Notes Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientID = @ParticipantID And ClientTypeID = 1 AND DeletedDate IS NULL
	UPDATE IntakeCalls Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID In
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ParticipantID)
	UPDATE IntakeBeds Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE IntakeID In
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ParticipantID)
	UPDATE Questionnaires Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE ClientTypeID = 1 AND DeletedDate IS NULL AND IntakeID In
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ParticipantID)
	UPDATE Assessments Set DeletedDate = @GetDate, DeletedBy = @UserName
		WHERE DeletedDate IS NULL AND IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ParticipantID)
	UPDATE ChildIntakes Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE DeletedDate IS NULL AND IntakeID In
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ParticipantID)
	UPDATE ClientSessions Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE DeletedDate IS NULL AND ClientTypeID = 2 AND ClientID In
		(SELECT ChildID FROM Children WHERE ParticipantID = @ParticipantID)
	UPDATE Referrals Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE DeletedDate IS NULL AND ClientTypeID = 2 AND ClientID In
		(SELECT ChildID FROM Children WHERE ParticipantID = @ParticipantID)
	UPDATE Notes Set DeletedDate = @GetDate, DeletedBy = @UserName 
		WHERE DeletedDate IS NULL AND ClientTypeID = 2 AND ClientID In
		(SELECT ChildID FROM Children WHERE ParticipantID = @ParticipantID)

proc_DeleteParticipantFile
CREATE PROCEDURE dbo.proc_DeleteParticipantFile
	(@FileID INT, @UserName VARCHAR(50))
	AS
	UPDATE ParticipantFiles
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE FileID = @FileID AND DeletedDate IS NULL

proc_DeleteParticipantIntake
CREATE PROCEDURE dbo.proc_DeleteParticipantIntake
	(@IntakeID INT, @UserName VARCHAR(50))
	AS
	DECLARE @GetDate DATETIME SET @GetDate = getdate()
	UPDATE ChildIntakes SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE ChildIntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID)
	UPDATE Referrals SET  DeletedDate = @GetDate, DeletedBy = @UserName WHERE ClientTypeID = 2 AND IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID)
	UPDATE IntakeBeds SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE ClientTypeID = 2 AND IntakeID IN 
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID)
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE ClientTypeID = 2 AND IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID)
	UPDATE Intakes SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID
	UPDATE IntakeBeds SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID AND ClientTypeID = 1
	UPDATE Referrals SET  DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID AND ClientTypeID = 1
	UPDATE ClientSessions SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID AND ClientTypeID = 1
	UPDATE Questionnaires SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID AND ClientTypeID = 1 AND DeletedDate IS NULL
	UPDATE Assessments SET DeletedDate = @GetDate, DeletedBy = @UserName WHERE IntakeID = @IntakeID AND DeletedDate IS NULL
	DELETE FROM IntakeCalls WHERE IntakeID = @IntakeID

proc_DeletePhase
CREATE PROCEDURE dbo.proc_DeletePhase  
	(@PhaseID INT, @UserName VARCHAR(50))  
	AS  
	UPDATE Phases  
	Set DeletedBy = @UserName, DeletedDate = getdate()  
	WHERE PhaseID = @PhaseID

proc_DeletePresentation
CREATE PROCEDURE dbo.proc_DeletePresentation
	(@PresentationID INT, @UserName VARCHAR(50))
	AS
	UPDATE Presentations
		Set DeletedDate = getdate(), DeletedBy = @UserName
	WHERE PresentationID = @PresentationID
	RETURN

proc_DeleteQuestion
CREATE PROCEDURE dbo.proc_DeleteQuestion
	(@QuestionID INT, @UserName VARCHAR(50))
	AS
	UPDATE Questions
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE QuestionID = @QuestionID AND DeletedDate IS NULL

proc_DeleteQuestionnaire
CREATE PROCEDURE dbo.proc_DeleteQuestionnaire
	(@QuestionnaireID INT, @UserName VARCHAR(50))
	AS
	UPDATE Questionnaires
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE QuestionnaireID = @QuestionnaireID AND DeletedDate IS NULL
	RETURN

proc_DeleteReferral
CREATE PROCEDURE dbo.proc_DeleteReferral
	(@ReferralID INT, @UserName VARCHAR(50))
	AS
	UPDATE Referrals
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE ReferralID = @ReferralID AND DeletedDate IS NULL
	UPDATE StaffReferrals SET DeletedBy = @UserName, DeletedDate = getdate()
	WHERE ReferralID = @ReferralID AND DeletedDate IS NULL

proc_DeleteReportNarrative
CREATE PROCEDURE dbo.proc_DeleteReportNarrative
	(@NarrativeID INT, @UserName VARCHAR(50))
	AS
	UPDATE ReportNarratives
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE NarrativeID = @NarrativeID AND DeletedDate IS NULL

proc_DeleteServiceSession
CREATE PROCEDURE dbo.proc_DeleteServiceSession
	(@SessionID INT, @UserName VARCHAR(50))
	AS
	UPDATE Sessions SET DeletedDate = getdate(), DeletedBy = @UserName WHERE SessionID = @SessionID
	UPDATE ClientSessions SET DeletedDate = getdate(), DeletedBy = @UserName WHERE SessionID = @SessionID
	UPDATE StaffSessions SET DeletedDate = getdate(), DeletedBy = @UserName WHERE SessionID = @SessionID
	RETURN

proc_DeleteStaffMember
CREATE PROCEDURE dbo.proc_DeleteStaffMember
	(@StaffID INT, @UserName VARCHAR(50))
	AS
	UPDATE Staff SET DeletedDate = getdate(), DeletedBy = @UserName WHERE StaffID = @StaffID

proc_DeleteSurvey
CREATE PROCEDURE dbo.proc_DeleteSurvey
	(@SurveyID INT, @UserName VARCHAR(50))
	AS
	UPDATE Surveys
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE SurveyID = @SurveyID AND DeletedDate IS NULL

proc_DeleteTask
CREATE PROCEDURE dbo.proc_DeleteTask
	(@TaskID INT, @UserName VARCHAR(50))
	AS
	UPDATE Tasks
	Set DeletedBy = @UserName, DeletedDate = getdate()
	WHERE TaskID = @TaskID AND DeletedDate IS NULL

proc_DeleteTrainingSession
CREATE PROCEDURE dbo.proc_DeleteTrainingSession
	(@SessionID INT, @UserName VARCHAR(50))
	AS
	UPDATE TrainingSessions
		Set DeletedDate = getdate(), DeletedBy = @UserName
	WHERE SessionID = @SessionID
	RETURN

proc_DeleteVolunteerActivity
CREATE PROCEDURE dbo.proc_DeleteVolunteerActivity
	(@ActivityID INT, @UserName VARCHAR(50))
	AS
	UPDATE VolunteerActivities
	SET DeletedDate = getdate(), DeletedBy = @UserName
	WHERE ActivityID = @ActivityID
	RETURN


proc_DuplicateDOBs
CREATE PROCEDURE dbo.proc_DuplicateDOBs  
	(@DOB SMALLDATETIME)  
	AS  
	SELECT [LastName] + ', ' + [FirstName] + ' ' + [MI] AS FullName  
	FROM Participants  
	WHERE DOB = @DOB  
	ORDER BY LastName, FirstName, MI  
	RETURN

proc_DuplicatedParticipants
CREATE PROCEDURE proc_DuplicatedParticipants
	AS
	SELECT ParticipantID, OptionalIdentifier, SSN, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB
	FROM Participants p
	WHERE ParticipantID IN 
		(
		SELECT ParticipantID
		FROM Participants
		WHERE DeletedDate IS NULL
			AND DOB IN
				(SELECT DOB	FROM Participants WHERE Participants.DeletedDate IS NULL GROUP BY DOB HAVING COUNT(DOB) > 1)
		 )
		 AND
		 (
			 LEFT(FirstName, 1) =
			 (
				SELECT TOP 1 LEFT(FirstName, 1) FROM Participants
				WHERE DOB = p.DOB AND ParticipantID <> p.ParticipantID
			 )
			 OR
			 LEFT(LastName, 1) =
			 (
				SELECT TOP 1 LEFT(LastName, 1) FROM Participants
				WHERE DOB = p.DOB AND ParticipantID <> p.ParticipantID
			 )
		)
	ORDER BY DOB, FullName

proc_EradicateAbuser
CREATE PROCEDURE dbo.proc_EradicateAbuser
	(@ID INT)
	AS
	DELETE FROM AbuserIntakes WHERE AbuserID = @ID
	DELETE FROM Notes WHERE ClientID = @ID AND ClientTypeID = 3
	DELETE FROM ClientSessions WHERE ClientID = @ID AND ClientTypeID = 3
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 3
	DELETE FROM Abusers WHERE AbuserID = @ID

proc_EradicateAbuserAlert
CREATE PROCEDURE dbo.proc_EradicateAbuserAlert
	(@ID INT)
	AS
	DELETE FROM AbuserAlertImages WHERE AlertID = @ID
	DELETE FROM AbuserAlerts WHERE AlertID = @ID

proc_EradicateAbuserIntake
CREATE PROCEDURE dbo.proc_EradicateAbuserIntake
	(@ID INT)
	AS
	DELETE FROM ClientSessions WHERE IntakeID = @ID AND ClientTypeID = 3
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Trips WHERE TripID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM SessionNotes WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID
		FROM Referrals
		WHERE ClientTypeID = 3 AND IntakeID = @ID)
	DELETE FROM Referrals WHERE IntakeID = @ID AND ClientTypeID = 3
	DELETE FROM AbuserIntakes WHERE AbuserIntakeID = @ID

proc_EradicateAlias
CREATE PROCEDURE dbo.proc_EradicateAlias
	(@ID INT)
	AS
	DELETE FROM Aliases WHERE AliasID = @ID

proc_EradicateAssessment
CREATE PROCEDURE dbo.proc_EradicateAssessment
	(@ID INT)
	AS
	DELETE FROM Assessments WHERE AssessmentID = @ID

proc_EradicateBed
CREATE PROCEDURE dbo.proc_EradicateBed
	(@ID INT)
	AS
		DELETE FROM RoomBedAssignments WHERE BedID = @ID
		DELETE FROM IntakeBeds WHERE BedID = @ID
		DELETE FROM Beds WHERE BedID = @ID

proc_EradicateBedAssignment
CREATE PROCEDURE dbo.proc_EradicateBedAssignment
	(@IntakeID INT, @ClientTypeID INT, @DateIn SMALLDATETIME)
	AS
	DELETE FROM IntakeBeds WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID AND DateIn = @DateIn

proc_EradicateCall
CREATE PROCEDURE dbo.proc_EradicateCall
	(@ID INT)
	AS
	DELETE FROM IntakeCalls WHERE CallID = @ID
	DELETE FROM HotlineReferrals WHERE CallID = @ID
	DELETE FROM ShelterRequests WHERE CallID = @ID
	DELETE FROM Calls WHERE CallID = @ID

proc_EradicateCampus
CREATE PROCEDURE dbo.proc_EradicateCampus
	(@ID INT)
	AS
	DELETE FROM Campuses WHERE CampusID = @ID

proc_EradicateChild
CREATE PROCEDURE dbo.proc_EradicateChild
	(@ID INT)
	AS
	DELETE FROM ChildAliases WHERE ChildID = @ID
	DELETE FROM IntakeBeds WHERE IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE ClientTypeID = 2 AND ChildID = @ID)
	DELETE FROM ChildIntakes WHERE ChildID = @ID
	DELETE FROM ClientSessions WHERE ClientID = @ID AND ClientTypeID = 2
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 2
	DELETE FROM Children WHERE ChildID = @ID

proc_EradicateChildAlias
CREATE PROCEDURE dbo.proc_EradicateChildAlias
	(@ID INT)
	AS
	DELETE FROM ChildAliases WHERE AliasID = @ID

proc_EradicateChildIntake
CREATE PROCEDURE dbo.proc_EradicateChildIntake
	(@ID INT)
	AS
	DELETE FROM ClientSessions WHERE IntakeID = @ID AND ClientTypeID = 2
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Trips WHERE TripID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM SessionNotes WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID
		FROM Referrals
		WHERE ClientTypeID = 2 AND IntakeID = @ID)
	DELETE FROM Referrals WHERE IntakeID = @ID AND ClientTypeID = 2
	DELETE FROM ChildAbsences WHERE ChildIntakeID = @ID
	DELETE FROM ChildIntakes WHERE ChildIntakeID = @ID

proc_EradicateClientSession
CREATE PROCEDURE dbo.proc_EradicateClientSession
	(@SessionID INT, @ClientID INT, @ClientTypeID INT)
	AS
	DELETE FROM ClientSessions WHERE SessionID = @SessionID AND ClientID = @ClientID AND ClientTypeID = @ClientTypeID 
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)

proc_EradicateCommunityMember
CREATE PROCEDURE dbo.proc_EradicateCommunityMember
	(@ID INT)
	AS
	DELETE FROM Interventions WHERE ClientID = @ID AND ClientTypeID = 4
	DELETE FROM Notes WHERE ClientID = @ID AND ClientTypeID = 4
	DELETE FROM ClientSessions WHERE ClientID = @ID AND ClientTypeID = 4
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Trips WHERE TripID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM SessionNotes WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID
		FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 4)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 4
	DELETE FROM CommunityMembers WHERE MemberID = @ID

proc_EradicateCredential
CREATE PROCEDURE dbo.proc_EradicateCredential
	(@ID INT)
	AS
	DELETE FROM StaffTraining WHERE SessionID IN
		(SELECT SessionID FROM TrainingSessions WHERE SubjectID = @ID)
	DELETE FROM StaffRequirements WHERE RequirementID = @ID
	DELETE FROM TrainingSessions WHERE SubjectID = @ID
	DELETE FROM Credentials WHERE CredentialID = @ID

proc_EradicateEmergencyContact
CREATE PROCEDURE dbo.proc_EradicateEmergencyContact
	(@ID INT)
	AS
	DELETE FROM EmerContacts WHERE EmerContactID = @ID

proc_EradicateGrant
CREATE PROCEDURE dbo.proc_EradicateGrant
	(@ID INT)
	AS
	DELETE FROM GrantTargets WHERE GrantID = @ID
	DELETE FROM GrantSurveys WHERE GrantID = @ID
	DELETE FROM Grants WHERE GrantID = @ID

proc_EradicateGrantor
CREATE PROCEDURE dbo.proc_EradicateGrantor
	(@ID INT)
	AS
	DELETE FROM ServiceMap WHERE GrantorID = @ID
	DELETE FROM GrantorServices WHERE GrantorID = @ID
	DELETE FROM GrantTargets WHERE GrantID IN
		(SELECT DISTINCT GrantID FROM Grants WHERE GrantorID = @ID)
	DELETE FROM Grants WHERE GrantorID = @ID	
	DELETE FROM Grantors WHERE GrantorID = @ID

proc_EradicateInfoRelease
CREATE PROCEDURE dbo.proc_EradicateInfoRelease
	(@ID INT)
	AS
	DELETE FROM ReleaseEntities WHERE ReleaseID = @ID
	DELETE FROM InfoReleases WHERE ReleaseID = @ID

proc_EradicateIntake
CREATE PROCEDURE dbo.proc_EradicateIntake
	(@ID INT)
	AS
	DELETE FROM IntakePhase WHERE IntakeID = @ID
	DELETE FROM IntakeStaff WHERE IntakeID = @ID
	DELETE FROM IntakeBeds WHERE IntakeID = @ID AND ClientTypeID = 1
	DELETE FROM IntakeBeds WHERE ClientTypeID = 2 AND IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @ID)
	DELETE FROM IntakeCalls WHERE IntakeID = @ID
	DELETE FROM IntakeVictimType WHERE IntakeID = @ID
	DELETE FROM AssessmentItems WHERE AssessmentID IN
		(SELECT AssessmentID FROM Assessments WHERE IntakeID = @ID)
	DELETE FROM Assessments WHERE IntakeID = @ID
	DELETE FROM ClientSessions WHERE IntakeID = @ID AND ClientTypeID = 1
	DELETE FROM ClientSessions WHERE ClientTypeID = 2 AND IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @ID)
	DELETE FROM Interventions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM Trips WHERE TripID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM SessionNotes WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM TangibleGoods WHERE SessionID IN
		(SELECT s.SessionID
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID
		FROM Referrals
		WHERE ClientTypeID = 1 AND IntakeID = @ID)
	DELETE FROM Referrals WHERE IntakeID = @ID AND ClientTypeID = 1
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID
		FROM Referrals WHERE ClientTypeID = 2 AND ClientID IN
			(SELECT ChildID FROM ChildIntakes WHERE IntakeID = @ID)
		)
	DELETE FROM Referrals WHERE ClientTypeID = 2 AND ClientID IN
		(SELECT ChildID FROM ChildIntakes WHERE IntakeID = @ID)
	DELETE FROM ChildAbsences WHERE ChildIntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @ID)
	DELETE FROM ChildIntakes WHERE IntakeID = @ID
	DELETE FROM Assessments WHERE IntakeID = @ID
	DELETE FROM Pets WHERE IntakeID = @ID
	DELETE FROM Intakes WHERE IntakeID = @ID

proc_EradicateIntervention
CREATE PROCEDURE dbo.proc_EradicateIntervention
	(@ID INT)
	AS
	DELETE FROM Interventions WHERE InterventionID = @ID	
	DECLARE @SessionID INT
	SET @SessionID = (SELECT TOP 1 SessionID FROM Interventions WHERE InterventionID = @ID)
	DELETE FROM ClientSessions WHERE SessionID = @SessionID
	DELETE FROM StaffSessions WHERE SessionID = @SessionID
	DELETE FROM Sessions WHERE SessionID = @SessionID

proc_EradicateNewShelter
CREATE PROCEDURE dbo.proc_EradicateNewShelter
	(@ShelterID INT)
	AS
	DELETE FROM Shelters WHERE ShelterID = @ShelterID

proc_EradicateNote
CREATE PROCEDURE dbo.proc_EradicateNote
	(@ID INT)
	AS
	DELETE FROM Notes WHERE NoteID = @ID

proc_EradicateParticipant
CREATE PROCEDURE dbo.proc_EradicateParticipant
	(@ID INT)
	AS
	DELETE FROM NarrativeResponses WHERE QuestionnaireID IN
		(SELECT QuestionnaireID FROM Questionnaires WHERE IntakeID IN
			(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID))
	DELETE FROM QuestionResponses WHERE QuestionnaireID IN
		(SELECT QuestionnaireID FROM Questionnaires WHERE IntakeID IN
			(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID))
	DELETE FROM Questionnaires WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeBeds WHERE ClientTypeID = 1 AND IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeBeds WHERE ClientTypeID = 2 AND IntakeID IN
		(SELECT ChildIntakeID FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID WHERE i.ParticipantID = @ID)
	DELETE FROM ChildIntakes WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeCalls WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakePhase WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeTasks WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeStaff WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM IntakeVictimType WHERE IntakeID IN
		(SELECT IntakeID FROM Intakes WHERE ParticipantID = @ID)
	DELETE FROM Intakes WHERE ParticipantID = @ID
	DELETE FROM ClientSessions WHERE ClientID = @ID AND ClientTypeID = 1
	DELETE FROM ClientSessions WHERE ClientTypeID = 2 AND ClientID IN
		(SELECT ChildID FROM Children WHERE ParticipantID = @ID)
	DELETE FROM Trips WHERE TripID IN
		(SELECT s.SessionID
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM TangibleGoods WHERE SessionID IN
		(SELECT s.SessionID
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffSessions WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM SessionNotes WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM [Sessions] WHERE SessionID IN
		(SELECT s.SessionID 
		FROM [Sessions] s LEFT OUTER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		WHERE cs.ClientID IS NULL)
	DELETE FROM StaffReferrals WHERE ReferralID IN
		(SELECT ReferralID FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 1)
	DELETE FROM Referrals WHERE ClientID = @ID AND ClientTypeID = 1
	DELETE FROM Referrals WHERE ClientTypeID = 2 AND ClientID IN
		(SELECT ChildID FROM Children WHERE ParticipantID = @ID)
	DELETE FROM Children WHERE ParticipantID = @ID
	DELETE FROM EmerContacts WHERE ParticipantID = @ID
	DELETE FROM Aliases WHERE ParticipantID = @ID
	DELETE FROM Notes WHERE ClientID = @ID AND ClientTypeID = 1
	DELETE FROM AbuserAlerts WHERE ParticipantID = @ID
	DELETE FROM ParticipantFiles WHERE ParticipantID = @ID
	DELETE FROM RHBA WHERE ParticipantID = @ID
	DELETE FROM ReleaseEntities WHERE ReleaseID IN
		(SELECT ReleaseID FROM InfoReleases WHERE ParticipantID = @ID)
	DELETE FROM InfoReleases WHERE ParticipantID = @ID
	DELETE FROM Participants WHERE ParticipantID = @ID

proc_EradicateParticipantFile
CREATE PROCEDURE dbo.proc_EradicateParticipantFile
	(@ID INT)
	AS
	DELETE FROM ParticipantFiles WHERE FileID = @ID

proc_EradicatePhase
CREATE PROCEDURE dbo.proc_EradicatePhase
	(@ID INT)
	AS
	DELETE FROM IntakePhase WHERE PhaseID = @ID
	DELETE FROM Phases WHERE PhaseID = @ID

proc_EradicatePresentation
CREATE PROCEDURE dbo.proc_EradicatePresentation
	(@ID INT)
	AS
	DELETE FROM StaffPresentations WHERE PresentationID = @ID
	DELETE FROM PresentationTopics WHERE PresentationID = @ID
	DELETE FROM Presentations WHERE PresentationID = @ID

proc_EradicateQuestionnaire
CREATE PROCEDURE dbo.proc_EradicateQuestionnaire
	(@ID INT)
	AS
	DELETE FROM NarrativeResponses WHERE QuestionnaireID = @ID 
	DELETE FROM QuestionResponses WHERE QuestionnaireID = @ID 
	DELETE FROM Questionnaires WHERE QuestionnaireID = @ID

proc_EradicateReferral
CREATE PROCEDURE dbo.proc_EradicateReferral
	(@ID INT)
	AS
	DELETE FROM StaffReferrals WHERE ReferralID = @ID
	DELETE FROM Referrals WHERE ReferralID = @ID

proc_EradicateReportNarrative
CREATE PROCEDURE dbo.proc_EradicateReportNarrative
	(@ID INT)
	AS
	DELETE FROM ReportNarratives WHERE NarrativeID = @ID

proc_EradicateRoom
CREATE PROCEDURE dbo.proc_EradicateRoom
	(@ID INT)
	AS
	DELETE FROM RoomBedAssignments WHERE RoomID = @ID
	DELETE FROM Rooms WHERE RoomID = @ID

proc_EradicateRoomBedAssignment
CREATE PROCEDURE dbo.proc_EradicateRoomBedAssignment
	(@ID INT)
	AS
	DELETE FROM RoomBedAssignments
	WHERE RoomBedAssignmentID = @ID

proc_EradicateServiceSession
CREATE PROCEDURE dbo.proc_EradicateServiceSession
	(@ID INT)
	AS
	DELETE FROM SessionNotes WHERE SessionID = @ID
	DELETE FROM StaffSessions WHERE SessionID = @ID
	DELETE FROM ClientSessions WHERE SessionID = @ID
	DELETE FROM Trips WHERE TripID = @ID
	DELETE FROM TangibleGoods WHERE SessionID = @ID
	DELETE FROM Interventions WHERE SessionID = @ID
	DELETE FROM [Sessions] WHERE SessionID = @ID

proc_EradicateShelter
CREATE PROCEDURE dbo.proc_EradicateShelter
	(@ID INT)
	AS
	DELETE FROM RoomBedAssignments WHERE BedID IN
		(SELECT BedID FROM Beds WHERE ShelterID = @ID)
	DELETE FROM RoomBedAssignments WHERE RoomID IN
			(SELECT RoomID FROM Rooms WHERE ShelterID = @ID)
	DELETE FROM Beds WHERE ShelterID = @ID
	DELETE FROM Rooms WHERE ShelterID = @ID
	DELETE FROM Shelters WHERE ShelterID = @ID

proc_EradicateStaffMember
CREATE PROCEDURE dbo.proc_EradicateStaffMember
	(@ID INT)
	AS
	DELETE FROM StaffPresentations WHERE StaffID = @ID
	DELETE FROM StaffTraining WHERE StaffID = @ID
	DELETE FROM StaffRequirements WHERE StaffID = @ID
	DELETE FROM IntakeStaff WHERE StaffID = @ID
	DELETE FROM StaffSessions WHERE StaffID = @ID
	DELETE FROM StaffReferrals WHERE StaffID = @ID
	DELETE FROM StaffCallService WHERE StaffID = @ID
	DELETE FROM VolunteerActivity WHERE StaffID = @ID
	DELETE FROM StaffExt WHERE StaffID = @ID
	DELETE FROM Staff WHERE StaffID = @ID

proc_EradicateSurvey
CREATE PROCEDURE dbo.proc_EradicateSurvey
	(@ID INT)
	AS
	DELETE FROM QuestionResponses WHERE QuestionnaireID IN
		(SELECT QuestionnaireID FROM Questionnaires WHERE SurveyID = @ID)
	DELETE FROM NarrativeResponses WHERE QuestionnaireID IN
		(SELECT QuestionnaireID FROM Questionnaires WHERE SurveyID = @ID)
	DELETE FROM Questionnaires WHERE SurveyID = @ID
	DELETE FROM SurveyQuestions WHERE SurveyID = @ID
	DELETE FROM SurveyNarratives WHERE SurveyID = @ID
	DELETE FROM GrantSurveys WHERE SurveyID = @ID
	DELETE FROM Surveys WHERE SurveyID = @ID

proc_EradicateTrainingSession
CREATE PROCEDURE dbo.proc_EradicateTrainingSession
	(@ID INT)
	AS
	DELETE FROM StaffTraining WHERE SessionID = @ID
	DELETE FROM TrainingSessions WHERE SessionID = @ID

proc_EradicateVolunteerActivity
CREATE PROCEDURE dbo.proc_EradicateVolunteerActivity
	(@ID INT)
	AS
	DELETE FROM VolunteerActivity WHERE ActivityID = @ID
	DELETE FROM VolunteerActivities WHERE ActivityID = @ID

proc_FillOtherArrays
CREATE PROCEDURE dbo.proc_FillOtherArrays 
	AS 
	SELECT * FROM xAbuserRelationship WHERE AbuserRelationshipID < 101; 
		SELECT * FROM xAbuserRelationship WHERE AbuserRelationshipID > 100 ORDER BY AbuserRelationship; 
	SELECT * FROM xCallSubject WHERE CallSubjectID < 101; 
		SELECT * FROM xCallSubject WHERE CallSubjectID > 100 ORDER BY CallSubject;
	SELECT * FROM xEthnicity WHERE EthnicityID < 101; 
		SELECT * FROM xEthnicity WHERE EthnicityID > 100 ORDER BY Ethnicity; 
	SELECT * FROM xExitDestination WHERE ExitDestinationID < 101; 
		SELECT * FROM xExitDestination WHERE ExitDestinationID > 100 ORDER BY ExitDestination; 
	SELECT * FROM xExitHousing WHERE ExitHousingID < 101 AND DeletedDate IS NULL ORDER BY DisplayOrder; 
		SELECT * FROM xExitHousing WHERE ExitHousingID > 100 ORDER BY ExitHousing; 
	SELECT * FROM xExitReason WHERE ExitReasonID < 101; 
		SELECT * FROM xExitReason WHERE ExitReasonID > 100 ORDER BY ExitReason; 
	SELECT * FROM xHotlineReferral WHERE HotlineReferralID < 101; 
		SELECT * FROM xHotlineReferral WHERE HotlineReferralID > 100 ORDER BY HotlineReferral; 
	SELECT * FROM xReasonDenied WHERE ReasonDeniedID < 101 ORDER BY ReasonDeniedID; 
		SELECT * FROM xReasonDenied WHERE ReasonDeniedID > 100 ORDER BY ReasonDenied; 
	SELECT * FROM xReferralSource WHERE ReferralSourceID < 101; 
		SELECT * FROM xReferralSource WHERE ReferralSourceID > 100 ORDER BY ReferralSource; 
	SELECT * FROM xReferralType WHERE ReferralTypeID < 100 ORDER BY ReferralType; 
		SELECT * FROM xReferralType WHERE ReferralTypeID > 99 ORDER BY ReferralType; 
	SELECT * FROM xPriorResidence WHERE PriorResidenceID < 101; 
		SELECT * FROM xPriorResidence WHERE PriorResidenceID > 100 ORDER BY PriorResidence

proc_FillProgramLookup
CREATE PROCEDURE dbo.proc_FillProgramLookup
	AS
	SELECT ProgramID, Program FROM 
		(SELECT ProgramID, Program, IsCurrent FROM Programs WHERE IsCurrent = 1 AND DeletedDate IS NULL 
		UNION ALL
		SELECT ProgramID, '*' + Program AS Program, IsCurrent FROM Programs WHERE IsCurrent = 0 AND DeletedDate IS NULL)
		AS sub ORDER BY IsCurrent DESC, Program;	

proc_FillServiceLookup
CREATE PROCEDURE dbo.proc_FillServiceLookup
	AS
	SELECT ServiceID, ServiceName FROM
	(SELECT ServiceID, ServiceName, IsCurrent = 1 FROM Services WHERE DiscontinuedDate IS NULL AND DeletedDate IS NULL
	UNION ALL
	SELECT ServiceID, '*' + ServiceName AS ServiceName, IsCurrent = 0 FROM Services WHERE DiscontinuedDate IS NOT NULL AND DeletedDate IS NULL)
	AS sub ORDER BY IsCurrent DESC, ServiceName;

proc_FillStaffLookups
CREATE PROCEDURE dbo.proc_FillStaffLookups
	AS
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Staff WHERE ServiceProvider = 1 And DateLeft Is Null And DeletedDate Is Null ORDER BY LastName, FirstName, MI;
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName, LastName, FirstName, MI FROM Staff WHERE ServiceProvider = 1 And DateLeft Is Null And DeletedDate Is Null
		UNION ALL
		SELECT StaffID, '*' + LastName + ', ' + FirstName + ' ' + MI AS FullName, LastName, FirstName, MI FROM Staff WHERE ServiceProvider = 1 And DateLeft IS NOT NULL And DeletedDate Is Null ORDER BY LastName, FirstName, MI;

proc_GetAbuser
CREATE PROCEDURE dbo.proc_GetAbuser 
	(@AbuserID INT)  
	AS 
	SELECT TOP 1 Abusers.*, TribeID
	FROM Abusers  LEFT OUTER JOIN TribalAffiliation On (Abusers.AbuserID = TribalAffiliation.ClientID And TribalAffiliation.ClientTypeID = 3)
	WHERE Abusers.AbuserID = @AbuserID And Abusers.DeletedDate IS NULL

proc_GetAbuserAlert
CREATE PROCEDURE dbo.proc_GetAbuserAlert
	(@AlertID INT)
	AS
	SELECT TOP 1 aa.*, aai.Image
	FROM AbuserAlerts aa LEFT OUTER JOIN AbuserAlertImages aai ON aa.AlertID = aai.AlertID
	WHERE aa.AlertID = @AlertID

proc_GetAbuserAlerts
CREATE PROCEDURE dbo.proc_GetAbuserAlerts
	(@CurrentOnly BIT)
	AS
	IF (@CurrentOnly = 1)
		BEGIN
			SELECT 
				AlertID, 
				p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
				a.LastName + ', ' + a.FirstName + ' ' + a.MI AS Abuser,
				AbuserRelationship
			FROM
				AbuserAlerts a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
					INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
					INNER JOIN xAbuserRelationship x ON a.AbuserRelationshipID = x.AbuserRelationshipID
			WHERE i.ExitDate IS NULL And a.DeletedDate IS NULL
			ORDER BY Participant
		END
	ELSE
		BEGIN
			SELECT DISTINCT
				AlertID, 
				p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
				a.LastName + ', ' + a.FirstName + ' ' + a.MI AS Abuser,
				AbuserRelationship
			FROM
				AbuserAlerts a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
					INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
					INNER JOIN xAbuserRelationship x ON a.AbuserRelationshipID = x.AbuserRelationshipID
			WHERE a.DeletedDate IS NULL
			ORDER BY Participant
		END

proc_GetAbuserData
CREATE PROCEDURE dbo.proc_GetAbuserData
	(@AbuserID INT)
	AS
	-- Abuser
	SELECT TOP 1 a.*, ta.TribeID
	FROM Abusers a LEFT OUTER JOIN TribalAffiliation ta ON a.AbuserID = ta.ClientID and ta.ClientTypeID = 3
	WHERE AbuserID = @AbuserID;
	-- Abuser Intakes
	SELECT AbuserIntakeID, EntryDate, ExitDate, ISNULL(x.CounselingStatus, 'Unknown') AS Status, 
		ISNULL(xcr.CounselingResult, 'Unknown') AS Result
	FROM AbuserIntakes ai LEFT OUTER JOIN xCounselingStatus x ON x.CounselingStatusID = ai.CounselingStatusID
		LEFT OUTER JOIN xCounselingResult xcr ON xcr.CounselingResultID = ai.CounselingResultID  
	WHERE AbuserID = @AbuserID
	ORDER BY EntryDate;
	-- Services
	SELECT cs.SessionID, SessionDate, ServiceName AS Service, Program, SessionHours, 
		s.NumberStaff, ISNULL(sf.LastName + ', ' + sf.FirstName, '') AS StaffName 
	FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID AND s.DeletedDate IS NULL
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
		LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
		LEFT OUTER JOIN Staff sf ON sts.StaffID = sf.StaffID AND sf.DeletedDate IS NULL
	WHERE cs.ClientID = @AbuserID AND cs.ClientTypeID = 3 AND cs.DeletedDate IS NULL
	ORDER BY SessionDate DESC;
	-- Referrals
	SELECT r.ReferralID, ReferralType, ReferralDate, NumberReferrals, Agency, ISNULL(LastName + ', ' + FirstName, '') AS StaffName
	FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
		LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
		LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
	WHERE ClientID = @AbuserID AND ClientTypeID = 3 And r.DeletedDate Is Null
	ORDER BY r.ReferralDate DESC;
	-- Notes
	SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Notes
	WHERE ClientID = @AbuserID And ClientTypeID = 3 And DeletedDate Is Null
	UNION ALL
	SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
	WHERE cs.ClientID = @AbuserID AND cs.ClientTypeID = 3 AND s.DeletedDate IS NULL	
	ORDER BY NoteType, NoteDate;

proc_GetAbuserIntake
CREATE PROCEDURE dbo.proc_GetAbuserIntake
	(@AbuserIntakeID INT)
	AS
	SELECT TOP 1 *
	FROM AbuserIntakes
	WHERE AbuserIntakeID = @AbuserIntakeID
	RETURN

proc_GetActivityClients
CREATE PROCEDURE dbo.proc_GetActivityClients
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	-- Current Participants, exit in last month, and those present during period
	SELECT DISTINCT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')',
		OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID  
	WHERE (p.DeletedDate IS NULL AND i.DeletedDate IS NULL) AND 
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate))
	ORDER BY FullName;
	-- Current Participant Opt'lIDs
	SELECT DISTINCT p.ParticipantID, OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID  
	WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate))
	ORDER BY OptionalIdentifier;
	-- Current/Recent Children + those present during period
	SELECT DISTINCT c.ChildID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ')'
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
	WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND
		(ci.ExitDate IS NULL OR -- Still present
		(ci.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (ci.EntryDate <= @ToDate AND ci.ExitDate >= @FromDate))
	ORDER BY FullName;
	-- Current Abusers + those present during period
	SELECT DISTINCT a.AbuserID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ')'
	FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
	WHERE a.DeletedDate IS NULL AND ai.DeletedDate IS NULL AND 
		(ai.ExitDate IS NULL OR -- Still present
		(ai.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (ai.EntryDate <= @ToDate AND ai.ExitDate >= @FromDate))
	ORDER BY FullName;
	-- Current Community Members
	SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM CommunityMembers
	WHERE DeletedDate IS NULL AND IsCurrent = 1
	ORDER BY FullName;
	-- Intake Data for current clients and those present during To/From period
	SELECT ParticipantID AS ClientID, ClientTypeID = 1, i.IntakeID, i.EntryDate AS EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL AND ParticipantID IN
		(SELECT p.ParticipantID
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID  
		WHERE (p.DeletedDate IS NULL) AND 
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate)))
	UNION ALL
	SELECT ChildID AS ClientID, ClientTypeID = 2, ci.ChildIntakeID, ci.EntryDate AS EntryDate, ci.ExitDate,
		CONVERT(VARCHAR(50), ci.EntryDate, 110) + ' - ' + CASE WHEN ci.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ci.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData  
	FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND ci.ChildID IN
		(SELECT ChildID FROM ChildIntakes WHERE DeletedDate IS NULL AND 
		(ci.ExitDate IS NULL OR -- Still present
		(ci.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (ci.EntryDate <= @ToDate AND ci.ExitDate >= @FromDate)))
	UNION ALL
	SELECT ai.AbuserID AS ClientID, ClientTypeID = 3, ai.AbuserIntakeID, ai.EntryDate AS EntryDate, ai.ExitDate,
		CONVERT(VARCHAR(50), ai.EntryDate, 110) + ' - ' + CASE WHEN ai.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ai.ExitDate, 110)  END + ' (' + p.Program + ')' AS IntakeData 
	FROM AbuserIntakes ai INNER JOIN Programs p ON ai.ProgramID = p.ProgramID
	WHERE ai.DeletedDate IS NULL AND ai.AbuserID IN
		(SELECT AbuserID FROM AbuserIntakes WHERE DeletedDate IS NULL AND 
		(ai.ExitDate IS NULL OR -- Still present
		(ai.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (ai.EntryDate <= @ToDate AND ai.ExitDate >= @FromDate)))
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 1, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 2, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 3, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	ORDER BY ClientTypeID, ClientID DESC, EntryDate DESC

proc_GetActivityClientsByEditDate
CREATE PROCEDURE dbo.proc_GetActivityClientsByEditDate
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	DECLARE @FirstSession SMALLDATETIME, @LastSession SMALLDATETIME
	SET @FirstSession = (SELECT MIN(SessionDate) FROM Sessions WHERE ModifiedDate BETWEEN @FromDate AND @ToDate)
	SET @LastSession = (SELECT MAX(SessionDate) FROM Sessions WHERE ModifiedDate BETWEEN @FromDate AND @ToDate)
	-- 	Current Participants, exit in last month, and those present during edited session dates
	SELECT DISTINCT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')',
		OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE p.DeletedDate IS NULL AND
		(ExitDate IS NULL -- Still present
		OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession)) -- present during edited session dates
	ORDER BY FullName;
	-- Current Participants OptionalIDs and those present during edited session dates
	SELECT DISTINCT p.ParticipantID, p.OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE p.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND
		(ExitDate IS NULL -- Still present
		OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession))
	ORDER BY OptionalIdentifier;
	-- 	Current Children, exit in last month, and those present during edited session dates
	SELECT c.ChildID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID AND ci.DeletedDate IS NULL
	WHERE c.DeletedDate IS NULL AND
		(ExitDate IS NULL -- Still present
		OR 	(ci.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession)) -- present during edited session dates
	ORDER BY FullName;
	-- Current Abusers and those present during edited session dates
	SELECT a.AbuserID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID AND ai.DeletedDate IS NULL
	WHERE a.DeletedDate IS NULL AND
		(ExitDate IS NULL -- Still present
		OR 	(ai.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession)) -- present during edited session dates
	ORDER BY FullName;
	-- Current Community Members
	SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM CommunityMembers
	WHERE DeletedDate IS NULL AND IsCurrent = 1
	ORDER BY FullName;	
	-- Intake Data for current clients and those present during edited session dates
	SELECT ParticipantID AS ClientID, ClientTypeID = 1, i.IntakeID, i.EntryDate AS EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL AND ParticipantID IN
		(SELECT ParticipantID FROM Intakes WHERE DeletedDate IS NULL AND 
			(ExitDate IS NULL -- Still present
			OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
			OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession))) -- present during edited session dates
	UNION ALL
	SELECT ChildID AS ClientID, ClientTypeID = 2, ci.ChildIntakeID, ci.EntryDate AS EntryDate, ci.ExitDate,
		CONVERT(VARCHAR(50), ci.EntryDate, 110) + ' - ' + CASE WHEN ci.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ci.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData  
	FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND ci.ChildID IN
		(SELECT ChildID FROM ChildIntakes WHERE DeletedDate IS NULL AND 
			(ExitDate IS NULL -- Still present
			OR 	(ci.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
			OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession)))
	UNION ALL
	SELECT ai.AbuserID AS ClientID, ClientTypeID = 3, ai.AbuserIntakeID, ai.EntryDate AS EntryDate, ai.ExitDate,
		CONVERT(VARCHAR(50), ai.EntryDate, 110) + ' - ' + CASE WHEN ai.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ai.ExitDate, 110)  END + ' (' + p.Program + ')' AS IntakeData 
	FROM AbuserIntakes ai INNER JOIN Programs p ON ai.ProgramID = p.ProgramID
	WHERE ai.DeletedDate IS NULL AND ai.AbuserID IN
		(SELECT AbuserID FROM AbuserIntakes WHERE DeletedDate IS NULL AND 
			(ExitDate IS NULL -- Still present
			OR 	(ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
			OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession))) -- present during edited session dates	
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 1, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 2, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 3, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData 
	ORDER BY ClientTypeID, ClientID DESC, EntryDate DESC;  

proc_GetActivityParticipants
CREATE PROCEDURE dbo.proc_GetActivityParticipants
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	-- Current Participants, Participants who left in one month, participants present during period
	SELECT DISTINCT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE (p.DeletedDate IS NULL) AND 
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate))
	ORDER BY FullName;
	-- Current Participant Opt'lIDs
	SELECT DISTINCT p.ParticipantID, OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE p.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate))
	ORDER BY OptionalIdentifier;
	-- Intake Data for current clients and those present during To/From period
	SELECT DISTINCT ParticipantID, i.IntakeID, i.EntryDate AS EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE ParticipantID IN
		(SELECT ParticipantID FROM Intakes WHERE DeletedDate IS NULL AND 
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (i.EntryDate <= @ToDate AND i.ExitDate >= @FromDate)))
	ORDER BY ParticipantID

proc_GetActivityParticipantsByEditDate
CREATE PROCEDURE dbo.proc_GetActivityParticipantsByEditDate
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	DECLARE @FirstSession SMALLDATETIME, @LastSession SMALLDATETIME
	SET @FirstSession = (SELECT MIN(SessionDate) FROM Sessions WHERE ModifiedDate BETWEEN @FromDate AND @ToDate)
	SET @LastSession = (SELECT MAX(SessionDate) FROM Sessions WHERE ModifiedDate BETWEEN @FromDate AND @ToDate)
	-- 	Current Participants, exit in last month, and those present during edited session dates
	SELECT DISTINCT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE p.DeletedDate IS NULL AND
		(ExitDate IS NULL -- Still present
		OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession)) -- present during edited session dates
	ORDER BY FullName;
	-- Current Participants OptionalIDs and those present during edited session dates
	SELECT DISTINCT p.ParticipantID, p.OptionalIdentifier
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE p.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND
		(ExitDate IS NULL -- Still present
		OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
		OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession))
	ORDER BY OptionalIdentifier;
	-- Intake Data for current participants and those present during edited session dates
	SELECT ParticipantID, i.IntakeID, i.EntryDate AS EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE ParticipantID IN
		(SELECT ParticipantID FROM Intakes WHERE DeletedDate IS NULL AND 
			(ExitDate IS NULL -- Still present
			OR 	(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())) -- Exit within one month
			OR (EntryDate <= @LastSession AND ExitDate >= @FirstSession))) -- present during edited session dates
	ORDER BY ParticipantID DESC, EntryDate DESC;

proc_GetAlias
CREATE PROCEDURE dbo.proc_GetAlias  
	(@AliasID INT)  
	AS  
	SELECT TOP 1 *  
	FROM Aliases  
	WHERE AliasID = @AliasID  

proc_GetAllBeds
CREATE PROCEDURE dbo.proc_GetAllBeds
	AS
	SELECT c.CampusID, c.CampusName, s.ShelterID, s.ShelterName, 
		b.BedID, b.Description, b.ServiceStart, b.ServiceEnd, b.IsCrib,
		rba.DateAssigned, rba.DateMoved, r.RoomID, r.RoomNumber
	FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
		INNER JOIN Beds b ON s.ShelterID = b.ShelterID
		LEFT OUTER JOIN RoomBedAssignments rba ON b.BedID = rba.BedID
		LEFT OUTER JOIN Rooms r ON rba.RoomID = r.RoomID
	WHERE s.DeletedDate IS NULL AND c.DeletedDate IS NULL AND b.DeletedDate IS NULL
		AND r.DeletedDate IS NULL
	ORDER BY c.CampusName, s.ShelterID, RoomNumber, b.Description

proc_GetAllClientsAndIntakeData
CREATE PROCEDURE dbo.proc_GetAllClientsAndIntakeData
	 AS
	-- Participants (with intakes) including Aliases
	SELECT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Participants p LEFT OUTER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE p.DeletedDate IS NULL AND i.ParticipantID IS NOT NULL
	UNION
	SELECT a.ParticipantID, FullName = a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  CONVERT(VARCHAR(50), DOB, 110) + ')'  
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID 
		LEFT OUTER JOIN Intakes i ON a.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE a.DeletedDate IS NULL AND i.ParticipantID IS NOT NULL
	ORDER BY FullName;
	-- ALL Participants (with intakes) Opt'lIDs
	SELECT DISTINCT p.ParticipantID, OptionalIdentifier
	FROM Participants p LEFT OUTER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE p.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND i.ParticipantID IS NOT NULL
	ORDER BY OptionalIdentifier;
	-- ALL Children (with intakes) including Aliases
	SELECT c.ChildID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ')'
	FROM Children c LEFT OUTER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID AND ci.DeletedDate IS NULL
	WHERE c.DeletedDate IS NULL AND ci.ChildID IS NOT NULL
	UNION
	SELECT ca.ChildID, FullName = ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ')'
	FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID AND c.DeletedDate IS NULL
		LEFT OUTER JOIN ChildIntakes ci ON ci.ChildID = c.ChildID AND ci.DeletedDate IS NULL
	WHERE ca.DeletedDate IS NULL AND ci.ChildID IS NOT NULL
	ORDER BY FullName;
	-- ALL Abusers (with intakes)
	SELECT DISTINCT a.AbuserID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ')'
	FROM Abusers a LEFT OUTER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID AND ai.DeletedDate IS NULL
	WHERE a.DeletedDate IS NULL AND ai.AbuserID IS NOT NULL
	ORDER BY FullName;
	-- ALL Community Members
	SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM CommunityMembers
	WHERE DeletedDate IS NULL
	ORDER BY FullName;
	-- Intake Data
	SELECT ParticipantID AS ClientID, ClientTypeID = 1, i.IntakeID, i.EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL
	UNION ALL
	SELECT ChildID AS ClientID, ClientTypeID = 2, ci.ChildIntakeID, ci.EntryDate, ci.ExitDate,
		CONVERT(VARCHAR(50), ci.EntryDate, 110) + ' - ' + CASE WHEN ci.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ci.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData  
	FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE ci.DeletedDate IS NULL
	UNION ALL
	SELECT ai.AbuserID AS ClientID, ClientTypeID = 3, ai.AbuserIntakeID, ai.EntryDate, ai.ExitDate,
		CONVERT(VARCHAR(50), ai.EntryDate, 110) + ' - ' + CASE WHEN ai.ExitDate IS NULL THEN 'Present'
		ELSE CONVERT(VARCHAR(50), ai.ExitDate, 110)  END + ' (' + p.Program + ')' AS IntakeData 
	FROM AbuserIntakes ai INNER JOIN Programs p ON ai.ProgramID = p.ProgramID
	WHERE ai.DeletedDate IS NULL
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 1, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 2, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	UNION ALL
	SELECT ClientID = 0, ClientTypeID = 3, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	ORDER BY ClientTypeID, ClientID DESC, EntryDate DESC;

proc_GetAllParticipantsAndIntakeData
CREATE PROCEDURE dbo.proc_GetAllParticipantsAndIntakeData
	 AS
	-- Participants (with intakes) including Aliases
	SELECT p.ParticipantID, FullName = LastName + ', ' + FirstName + ' ' + MI + ' (' +  CONVERT(VarChar(50), DOB, 110) + ')'
	FROM Participants p LEFT OUTER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE p.DeletedDate IS NULL AND i.ParticipantID IS NOT NULL
	UNION
	SELECT a.ParticipantID, FullName = a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  CONVERT(VARCHAR(50), DOB, 110) + ')'  
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID 
		LEFT OUTER JOIN Intakes i ON a.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
	WHERE a.DeletedDate IS NULL AND i.ParticipantID IS NOT NULL
	ORDER BY FullName;
	-- ALL Participants (with intakes) Opt'lIDs
	SELECT DISTINCT p.ParticipantID, OptionalIdentifier
	FROM Participants p LEFT OUTER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL  
	WHERE p.DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0 AND i.ParticipantID IS NOT NULL
	ORDER BY OptionalIdentifier;
	-- Intake Data
	SELECT ParticipantID, i.IntakeID, i.EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL
	UNION ALL
	SELECT ParticipantID = 0, IntakeID = 0, NULL, NULL, 'Service NOT during intake period' AS IntakeData
	ORDER BY ParticipantID DESC, EntryDate DESC;

proc_GetAssessment
CREATE PROCEDURE dbo.proc_GetAssessment
	(@AssessmentID INT)
	AS
	SELECT TOP 1 IntakeID, AssessmentDate, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate
	FROM Assessments
	WHERE AssessmentID = @AssessmentID;
	SELECT DomainID, StatusID
	FROM AssessmentItems
	WHERE AssessmentID = @AssessmentID
	ORDER BY DomainID

proc_GetAssessmentItems
CREATE PROCEDURE dbo.proc_GetAssessmentItems
	AS
	SELECT md.Domain, ds.DomainID, ms.Status, ds.StatusID, ds.Criterion
	FROM DomainStatus ds INNER JOIN MatrixDomains md ON ds.DomainID = md.DomainID
		INNER JOIN MatrixStatus ms ON ms.StatusID = ds.StatusID
	ORDER BY ds.DomainID, ds.StatusID;

proc_GetAssessments
CREATE PROCEDURE dbo.proc_GetAssessments
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByEditDate BIT)
	AS
	IF @ByEditDate = 0
	BEGIN
		SELECT p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
			CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + 
				CASE WHEN i.ExitDate IS NULL THEN 'Present'
					 ELSE CONVERT(VARCHAR(50), i.ExitDate, 110) END AS Intake,
			a.AssessmentDate, a.ModifiedBy, a.ModifiedDate, a.AssessmentID    
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
			INNER JOIN Assessments a ON a.IntakeID = i.IntakeID
		WHERE a.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
			AND a.AssessmentDate BETWEEN @FromDate AND @ToDate
		ORDER BY AssessmentDate;
	END
	ELSE
	BEGIN
		SELECT p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
			CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + 
				CASE WHEN i.ExitDate IS NULL THEN 'Present'
					 ELSE CONVERT(VARCHAR(50), i.ExitDate, 110) END AS Intake,
			a.AssessmentDate, a.ModifiedBy, a.ModifiedDate, a.AssessmentID    
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
			INNER JOIN Assessments a ON a.IntakeID = i.IntakeID
		WHERE a.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
			AND a.ModifiedDate BETWEEN @FromDate AND @ToDate
		ORDER BY AssessmentDate;		
	END

proc_GetBackupData
CREATE PROCEDURE dbo.proc_GetBackupData 
	AS 
	SELECT TOP 1 BackupDate, BackupPath, TempPath, BackupAutomatic, BackupFrequency, BackupOnServer 
	FROM zsSettings

proc_GetBed
CREATE PROCEDURE dbo.proc_GetBed
	(@BedID INT)
	AS
	SELECT TOP 1 Beds.*, ShelterName
	FROM Beds Inner Join Shelters On Beds.ShelterID = Shelters.ShelterID
	WHERE BedID = @BedID
	RETURN

proc_GetBedAssignments
CREATE PROCEDURE dbo.proc_GetBedAssignments
	(@AsOfDate SMALLDATETIME)
	AS
	DECLARE @MaxDate SMALLDATETIME SET @MaxDate = '6/6/2079'	
	-- Resident Participants assigned to beds
	SELECT LastName + ', ' + FirstName + ' ' + MI + ' (P)' as FullName, p.Sex, i.IntakeID, ChildIntakeID = 0, ClientTypeID = 1, 
		ib.BedID, ib.CreatedDate, ib.CreatedBy, DateIn, DateOut, s.CampusID
	FROM
		Participants p INNER JOIN Intakes i On p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeBeds ib On i.IntakeID = ib.IntakeID And ClientTypeID = 1
		INNER JOIN Beds b On ib.BedID = b.BedID
		INNER JOIN Shelters s On s.ShelterID = b.ShelterID
	WHERE
		ib.DeletedDate Is Null And i.DeletedDate IS NULL And p.DeletedDate IS NULL
		And
		(@AsOfDate >= DateIn And @AsOfDate < IsNull(DateOut, @MaxDate))
	UNION 
	-- Resident Children assigned to beds
	SELECT LastName + ', ' + FirstName + ' ' + MI + ' (C)' as FullName, c.Sex, ci.IntakeID, ci.ChildIntakeID, ClientTypeID = 2, 
		ib.BedID, ib.CreatedDate, ib.CreatedBy, DateIn, DateOut, s.CampusID
	FROM 
		Children c INNER JOIN ChildIntakes ci On c.ChildID = ci.ChildID
		INNER JOIN IntakeBeds ib On ci.ChildIntakeID = ib.IntakeID And ClientTypeID = 2
		INNER JOIN Beds b On ib.BedID = b.BedID
		INNER JOIN Shelters s On s.ShelterID = b.ShelterID
		INNER JOIN Intakes i On ci.IntakeID = i.IntakeID				
	WHERE
		ib.DeletedDate Is Null And ci.DeletedDate IS NULL And i.DeletedDate IS NULL And c.DeletedDate IS NULL
		And
		(@AsOfDate >= DateIn And @AsOfDate < IsNull(DateOut, @MaxDate))
	UNION
	-- Resident Participants NOT assigned to a bed on specified date
	SELECT LastName + ', ' + FirstName + ' ' + MI + ' (P)' as FullName, p.Sex, i.IntakeID, ChildIntakeID = 0, 
		ClientTypeID = 1, BedID = 0, CreatedDate = NULL, CreatedBy = '', DateIn = NULL, DateOut = NULL, s.CampusID
	FROM Participants p INNER JOIN Intakes i on p.ParticipantID = i.ParticipantID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE 
		i.IntakeTypeID IN (1, 2, 3, 5)  -- Resident Intake (Crisis/Transitional/Homeless/Other Resident)
		And
		i.DeletedDate IS NULL And p.DeletedDate IS NULL
		And
		(@AsOfDate >= EntryDate and @AsOfDate < IsNull(ExitDate, @MaxDate)) -- Specified date within intake period
		And
		IntakeID NOT IN		-- Not assigned a bed on specified date
			(SELECT IntakeID 
			FROM IntakeBeds 
			WHERE IntakeBeds.DeletedDate Is Null And ClientTypeID = 1 And (@AsOfDate >= DateIn And @AsOfDate < IsNull(DateOut, @MaxDate)))
	UNION
	-- Resident Children NOT assigned a bed on specified date
	SELECT LastName + ', ' + FirstName + ' ' + MI + ' (C)' as FullName, c.Sex, ci.IntakeID, ci.ChildIntakeID, 
		ClientTypeID = 2, BedID = 0, CreatedDate = NULL, CreatedBy = '', DateIn = NULL, DateOut = NULL, s.CampusID
	FROM (Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID) 
		INNER JOIN Intakes i on ci.IntakeID = i.IntakeID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE
		i.IntakeTypeID IN (1, 2, 3, 5) And i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND c.DeletedDate IS NULL
		And 
		(@AsOfDate >= ci.EntryDate And @AsOfDate < IsNull(ci.ExitDate, @MaxDate))
		And
		ci.ChildIntakeID NOT IN
			(SELECT IntakeID
			 FROM IntakeBeds
			 WHERE IntakeBeds.DeletedDate Is Null And ClientTypeID = 2 And (@AsOfDate >= DateIn And @AsOfDate < IsNull(DateOut, @MaxDate)))

proc_GetCall
CREATE PROCEDURE dbo.proc_GetCall 
	(@CallID INT) 
	AS 
	SELECT TOP 1 c.*, sr.*, ISNULL(ic.IntakeID, 0) AS IntakeID 
	FROM Calls c LEFT JOIN ShelterRequests sr ON c.CallID = sr.CallID 
		LEFT OUTER JOIN IntakeCalls ic ON ic.CallID = c.CallID
	WHERE c.CallID = @CallID;
	SELECT HotlineReferralID FROM HotlineReferrals WHERE CallID = @CallID;
	SELECT * FROM CallServices WHERE CallID = @CallID;
	SELECT * FROM StaffCallService WHERE SessionID IN
		(SELECT SessionID FROM CallServices WHERE CallID = @CallID)

proc_GetCallsAndWalkIns
CREATE PROCEDURE dbo.proc_GetCallsAndWalkIns 
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByCallDate BIT)
	AS 
		IF @ByCallDate = 1 
			SELECT ShelterName, c.CallID, CallDate, c.ModifiedDate, CallTypeID, CallSubjectID, IsNull(IntakeID, 0) AS IntakeID,
				sr.CallID AS Requested, RequestOutcomeID, LastName + ', ' + FirstName AS Caller, c.WalkIn 
			FROM Shelters s INNER JOIN Calls c ON s.ShelterID = c.ShelterID
				LEFT OUTER JOIN ShelterRequests sr ON c.CallID = sr.CallID
				LEFT OUTER JOIN IntakeCalls ic ON ic.CallID = c.CallID
			WHERE (CallDate Between @FromDate And @ToDate) And c.DeletedDate Is Null 
			ORDER BY CallDate 
		ELSE	
			SELECT ShelterName, c.CallID, CallDate, c.ModifiedDate, CallTypeID, CallSubjectID,  IsNull(IntakeID, 0) AS IntakeID,
				sr.CallID AS Requested, RequestOutcomeID, LastName + ', ' + FirstName AS Caller, c.WalkIn 
			FROM Shelters s INNER JOIN Calls c ON s.ShelterID = c.ShelterID
				LEFT OUTER JOIN ShelterRequests sr ON c.CallID = sr.CallID
				LEFT OUTER JOIN IntakeCalls ic ON ic.CallID = c.CallID
			WHERE (c.ModifiedDate Between @FromDate And @ToDate) And c.DeletedDate Is Null 
			ORDER BY CallDate

proc_GetChild
CREATE PROCEDURE dbo.proc_GetChild (@ChildID INT)  
	AS  
	SELECT TOP 1 Children.*, TribeID  
	FROM Children LEFT OUTER JOIN TribalAffiliation On (Children.ChildID = TribalAffiliation.ClientID And TribalAffiliation.ClientTypeID = 2)  
	WHERE Children.ChildID = @ChildID And Children.DeletedDate IS NULL  
	RETURN

proc_GetChildAlias
CREATE PROCEDURE dbo.proc_GetChildAlias
	(@AliasID INT)  
	AS  
	SELECT TOP 1 *  
	FROM ChildAliases  
	WHERE AliasID = @AliasID

proc_GetChildData
CREATE PROCEDURE dbo.proc_GetChildData
	(@ChildID INT)
	AS
	-- Child, TribeID, ParentName
	SELECT TOP 1 c.*, ta.TribeID, ParentName = 
		(SELECT TOP 1 LastName + ', ' + FirstName + ' ' + MI AS ParentName 
		FROM Participants WHERE ParticipantID IN
			(SELECT ParticipantID FROM Children WHERE ChildID = @ChildID))
	FROM Children c LEFT OUTER JOIN TribalAffiliation  ta On (c.ChildID = ta.ClientID And ta.ClientTypeID = 2)
	WHERE ChildID = @ChildID;
	-- Aliases
	SELECT * FROM ChildAliases WHERE ChildID = @ChildID AND DeletedDate IS NULL;
	-- Child Intakes
	SELECT ci.IntakeID, ci.ChildIntakeID, ci.EntryDate, ci.ExitDate, s.ShelterName, x.IntakeType
	FROM Intakes i INNER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
	WHERE ci.ChildID = @ChildID And i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
	ORDER BY EntryDate;	
	-- Services
	SELECT cs.SessionID, SessionDate, ServiceName AS Service, Program, SessionHours, 
		s.NumberStaff, ISNULL(sf.LastName + ', ' + sf.FirstName, '') AS StaffName 
	FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID AND s.DeletedDate IS NULL
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
		LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
		LEFT OUTER JOIN Staff sf ON sts.StaffID = sf.StaffID AND sf.DeletedDate IS NULL
	WHERE cs.ClientID = @ChildID AND cs.ClientTypeID = 2 AND cs.DeletedDate IS NULL
	ORDER BY SessionDate DESC;
	-- Referrals
	SELECT r.ReferralID, ReferralType, ReferralDate, NumberReferrals, Agency, ISNULL(LastName + ', ' + FirstName, '') AS StaffName
	FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
		LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
		LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
	WHERE ClientID = @ChildID AND ClientTypeID = 2 And r.DeletedDate Is Null
	ORDER BY r.ReferralDate DESC;
	-- Notes
	SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Notes
	WHERE ClientID = @ChildID And ClientTypeID = 2 And DeletedDate Is Null
	UNION ALL
	SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
	WHERE cs.ClientID = @ChildID AND cs.ClientTypeID = 2 AND s.DeletedDate IS NULL	
	ORDER BY NoteType, NoteDate;

proc_GetChildren
CREATE PROCEDURE dbo.proc_GetChildren  
	(@ParticipantID INT) 
	AS 
	SELECT Children.*, TribeID  
	FROM Children LEFT OUTER JOIN TribalAffiliation On (Children.ChildID = TribalAffiliation.ClientID And TribalAffiliation.ClientTypeID = 2)
	WHERE (ParticipantID = @ParticipantID) AND (DeletedDate IS NULL)  
	ORDER BY DOB  
	RETURN

proc_GetClientIntakes
CREATE PROCEDURE dbo.proc_GetClientIntakes
	(@ClientID INT, @ClientTypeID INT)
	AS
	-- Participant Intakes
	IF @ClientTypeID = 1
		BEGIN
			SELECT IntakeID, EntryDate, ExitDate, s.ShelterName, x.IntakeType
			FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
				INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
			WHERE ParticipantID = @ClientID And i.DeletedDate IS NULL
			ORDER BY EntryDate		
		END
	-- Child Intakes
	ELSE IF @ClientTypeID = 2
		BEGIN
			SELECT ci.IntakeID, ci.EntryDate, ci.ExitDate, s.ShelterName, x.IntakeType 
			FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
				INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
				INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
			WHERE ci.ChildID = @ClientID AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			ORDER BY ci.EntryDate		
		END
	-- Abuser Intakes
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT ai.AbuserIntakeID, ai.EntryDate, ai.ExitDate, xcs.CounselingStatus, xcr.CounselingResult
			FROM AbuserIntakes ai INNER JOIN xCounselingStatus xcs ON ai.CounselingStatusID = xcs.CounselingStatusID
				INNER JOIN xCounselingResult xcr ON ai.CounselingResultID = xcr.CounselingResultID
			WHERE ai.AbuserID = @ClientID AND ai.DeletedDate IS NULL
			ORDER BY ai.EntryDate
		END

proc_GetClientNotes
CREATE PROCEDURE dbo.proc_GetClientNotes
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByNoteDate BIT)
	AS
	IF @ByNoteDate = 1
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (P)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Participants p INNER JOIN Notes n ON p.ParticipantID = n.ClientID And ClientTypeID = 1
		WHERE NoteDate Between @FromDate And @ToDate And p.DeletedDate IS NULL And n.DeletedDate IS NULL		
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (C)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Children c INNER JOIN Notes n On c.ChildID = n.ClientID And ClientTypeID = 2
		WHERE NoteDate Between @FromDate And @ToDate And c.DeletedDate IS NULL And n.DeletedDate IS NULL
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (A)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Abusers a INNER JOIN Notes n On a.AbuserID = n.ClientID And ClientTypeID = 3
		WHERE NoteDate Between @FromDate And @ToDate And a.DeletedDate IS NULL And n.DeletedDate IS NULL
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (M)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID	
		FROM CommunityMembers cm INNER JOIN Notes n ON cm.MemberID = n.ClientID AND ClientTypeID = 4
		WHERE NoteDate BETWEEN @FromDate AND @ToDate AND cm.DeletedDate IS NULL AND n.DeletedDate IS NULL	
		ORDER BY NoteDate
	ELSE
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (P)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Participants p INNER JOIN Notes n On p.ParticipantID = n.ClientID And ClientTypeID = 1
		WHERE n.ModifiedDate Between @FromDate And @ToDate And p.DeletedDate IS NULL And n.DeletedDate IS NULL
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (C)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Children c INNER JOIN Notes n On c.ChildID = n.ClientID And ClientTypeID = 2
		WHERE n.ModifiedDate Between @FromDate And @ToDate And c.DeletedDate IS NULL And n.DeletedDate IS NULL
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (A)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM Abusers a INNER JOIN Notes n On a.AbuserID = n.ClientID And ClientTypeID = 3
		WHERE n.ModifiedDate Between @FromDate And @ToDate And a.DeletedDate IS NULL And n.DeletedDate IS NULL
		UNION ALL
		SELECT LastName + ', ' + FirstName + ' ' + MI + ' (M)' as FullName, NoteID, NoteDate, Subject, 
		NoteText = CASE WHEN LEN(NoteText) < 70 THEN NoteText ELSE LEFT(NoteText, 70) + '...' END, 
		ClientTypeID, n.ModifiedDate, ClientID
		FROM CommunityMembers cm INNER JOIN Notes n ON cm.MemberID = n.ClientID AND ClientTypeID = 4
		WHERE n.ModifiedDate BETWEEN @FromDate AND @ToDate AND cm.DeletedDate IS NULL AND n.DeletedDate IS NULL
		ORDER BY ModifiedDate

proc_GetClientReferrals
CREATE PROCEDURE dbo.proc_GetClientReferrals
	(@ClientID INT, @ClientTypeID INT)
	AS
	SELECT r.ReferralID, ReferralType, ReferralDate, NumberReferrals, Agency, LastName + ', ' + FirstName AS StaffName
	FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
		LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
		LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
	WHERE ClientID = @ClientID AND ClientTypeID = @ClientTypeID And r.DeletedDate Is Null
	ORDER BY ReferralID

proc_GetClients
CREATE PROCEDURE dbo.proc_GetClients
	(@All BIT)
	AS
	IF @All = 1
		BEGIN
			SELECT ParticipantID, OptionalIdentifier, FullName = CASE
				WHEN ReturnStatusID = 1 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [A]'
				WHEN ReturnStatusID = 2 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [B]'
				WHEN ReturnStatusID = 3 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [C]'
				WHEN ReturnStatusID = 4 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [D]'
				END
			FROM Participants 
			WHERE DeletedDate IS NULL
			UNION
			SELECT a.ParticipantID, OptionalIdentifier, FullName = CASE
				WHEN ReturnStatusID = 1 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [A]' 
				WHEN ReturnStatusID = 2 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [B]'
				WHEN ReturnStatusID = 3 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [C]'
				WHEN ReturnStatusID = 4 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [D]'
				END
			FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID 
			WHERE a.DeletedDate IS NULL And p.DeletedDate IS NULL
			ORDER BY FullName;
				
			SELECT ParticipantID, ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName  
			FROM Children  
			WHERE DeletedDate IS NULL
			UNION
			SELECT c.ParticipantID, ca.ChildID, ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName
			FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID
			WHERE ca.DeletedDate IS NULL AND c.DeletedDate IS NULL
			ORDER BY FullName;
			
			SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')'  AS FullName  
			FROM Abusers  
			WHERE DeletedDate IS NULL  
			ORDER BY LastName, FirstName, MI, DOB;  
			
			SELECT ParticipantID, OptionalIdentifier
			FROM Participants
			WHERE DeletedDate IS NULL AND LEN(OptionalIdentifier) > 0
			ORDER BY OptionalIdentifier;
			
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
			FROM CommunityMembers
			WHERE DeletedDate IS NULL
			ORDER BY LastName, FirstName, MI
		END
	ELSE
		BEGIN
			SELECT Participants.ParticipantID, IntakeID, OptionalIdentifier, FullName = CASE
				WHEN ReturnStatusID = 1 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [A]'  
				WHEN ReturnStatusID = 2 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [B]'  
				WHEN ReturnStatusID = 3 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [C]'  
				WHEN ReturnStatusID = 4 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [D]'  
				END
			FROM Participants INNER JOIN Intakes ON Participants.ParticipantID = Intakes.ParticipantID  
			WHERE (Participants.DeletedDate IS NULL) AND (Intakes.DeletedDate IS NULL) AND (Intakes.ExitDate IS NULL)
			UNION
			SELECT a.ParticipantID, IntakeID, OptionalIdentifier, FullName = CASE
				WHEN ReturnStatusID = 1 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [A]'  
				WHEN ReturnStatusID = 2 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [B]'  
				WHEN ReturnStatusID = 3 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [C]'  
				WHEN ReturnStatusID = 4 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' +  Convert(VarChar(50), DOB, 110) + ')    [D]'   
				END
			FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
				INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
			WHERE a.DeletedDate IS NULL AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL and i.ExitDate IS NULL
			ORDER BY FullName;
			
			SELECT c.ParticipantID, c.ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')' AS FullName, IntakeID  
			FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID  
			WHERE (c.DeletedDate IS NULL) AND (ci.DeletedDate IS NULL) AND (ci.ExitDate IS NULL)
			UNION
			SELECT c.ParticipantID, ca.ChildID, ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI + ' (' + CONVERT(VarChar(50), DOB, 110) + ')' AS FullName, IntakeID
			FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID
				INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID 
			WHERE ca.DeletedDate IS NULL AND c.DeletedDate IS NULL AND ci.ExitDate IS NULL
			ORDER BY FullName;

			SELECT Abusers.AbuserID, LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')' AS FullName  
			FROM Abusers INNER JOIN AbuserIntakes ON Abusers.AbuserID = AbuserIntakes.AbuserID  
			WHERE (Abusers.DeletedDate IS NULL) AND (AbuserIntakes.DeletedDate IS NULL) AND (AbuserIntakes.ExitDate IS NULL)  
			ORDER BY LastName, FirstName, MI, DOB;  
	
			SELECT p.ParticipantID, OptionalIdentifier
			FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID  
			WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND i.ExitDate IS NULL AND LEN(OptionalIdentifier) > 0
			ORDER BY OptionalIdentifier;
			
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
			FROM CommunityMembers
			WHERE DeletedDate IS NULL AND IsCurrent = 1
			ORDER BY LastName, FirstName, MI
		END

proc_GetClientServiceSessions
CREATE PROCEDURE dbo.proc_GetClientServiceSessions
	(@ClientTypeID INT, @ClientID INT)
	AS
	SELECT cs.SessionID, SessionDate, ServiceName AS Service, Program, SessionHours, 
		s.NumberStaff, ISNULL(sf.LastName + ', ' + sf.FirstName, '') AS StaffName 
	FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID AND s.DeletedDate IS NULL
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
		LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
		LEFT OUTER JOIN Staff sf ON sts.StaffID = sf.StaffID AND sf.DeletedDate IS NULL
	WHERE cs.ClientID = @ClientID AND cs.ClientTypeID = @ClientTypeID AND cs.DeletedDate IS NULL
	ORDER BY SessionDate DESC

proc_GetCommunityMember
CREATE PROCEDURE dbo.proc_GetCommunityMember
	(@MemberID INT)
	AS
	SELECT TOP 1 cm.*, ISNULL(TribeID, -1) AS TribeID
	FROM CommunityMembers cm LEFT OUTER JOIN TribalAffiliation  ta On (cm.MemberID = ta.ClientID And ta.ClientTypeID = 4)
	WHERE cm.MemberID = @MemberID  And cm.DeletedDate IS NULL;
	SELECT cs.SessionID, SessionDate, ServiceName AS Service, Program, SessionHours, 
		s.NumberStaff, ISNULL(sf.LastName + ', ' + sf.FirstName, '') AS StaffName 
	FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID AND s.DeletedDate IS NULL
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
		LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
		LEFT OUTER JOIN Staff sf ON sts.StaffID = sf.StaffID AND sf.DeletedDate IS NULL
	WHERE cs.ClientID = @MemberID AND cs.ClientTypeID = 4 AND cs.DeletedDate IS NULL
	ORDER BY SessionDate DESC;
	SELECT r.ReferralID, ReferralType, ReferralDate, NumberReferrals, Agency, ISNULL(LastName + ', ' + FirstName, '') AS StaffName
	FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
		LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
		LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
	WHERE ClientID = @MemberID AND ClientTypeID = 4 And r.DeletedDate Is Null
	ORDER BY r.ReferralDate DESC;
	SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Notes
	WHERE ClientID = @MemberID And ClientTypeID = 4 And DeletedDate Is Null
	UNION ALL
	SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
	WHERE cs.ClientID = @MemberID AND cs.ClientTypeID = 4 AND s.DeletedDate IS NULL	
	ORDER BY NoteType, NoteDate;

proc_GetCommunityMembers
CREATE PROCEDURE dbo.proc_GetCommunityMembers
	(@AllMembers BIT)
	AS
	IF @AllMembers = 1
		BEGIN
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
			FROM CommunityMembers
			WHERE DeletedDate IS NULL
			ORDER BY LastName, FirstName, MI
		END
	ELSE
		BEGIN
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
			FROM CommunityMembers
			WHERE DeletedDate IS NULL AND IsCurrent = 1
			ORDER BY LastName, FirstName, MI
		END

proc_GetCredential
CREATE PROCEDURE dbo.proc_GetCredential
	(@CredentialID INT)
	AS
	SELECT c.*, sr.StaffID
	FROM (Staff s INNER JOIN StaffRequirements sr ON s.StaffID = sr.StaffID 
		AND s.DeletedDate IS NULL AND s.DateLeft IS NULL)
		RIGHT OUTER JOIN Credentials c ON sr.RequirementID = c.CredentialID
	WHERE c.CredentialID = @CredentialID

proc_GetCredentials
CREATE PROCEDURE dbo.proc_GetCredentials
	(@CurrentOnly BIT)
	AS
	IF @CurrentOnly = 0
		SELECT CredentialID, c.Credential, IsCurrent, Display = CASE
				WHEN IsCurrent = 1 THEN c.Credential ELSE '*' + c.Credential END,
			Required = CASE WHEN Frequency > -2 THEN 'Yes' ELSE 'No' END,
			Training = CASE WHEN IsSubject = 1 THEN 'Yes' ELSE 'No' END,
			Frequency = CASE 
				WHEN c.Frequency = -2 THEN 'N/A'
				WHEN c.Frequency = -1 THEN 'Manual'
				WHEN c.Frequency = 0 THEN 'One-time'
				ELSE CAST(c.Frequency AS VARCHAR(4)) END
		FROM Credentials c
		WHERE DeletedDate Is Null 
		ORDER BY c.Credential
	ELSE
		SELECT CredentialID, c.Credential, IsCurrent, Display = c.Credential,
			Required = CASE WHEN Frequency > -2 THEN 'Yes' ELSE 'No' END,
			Training = CASE WHEN IsSubject = 1 THEN 'Yes' ELSE 'No' END,
			Frequency = CASE 
				WHEN c.Frequency = -2 THEN 'N/A'
				WHEN c.Frequency = -1 THEN 'Manual'
				WHEN c.Frequency = 0 THEN 'One-time'
				ELSE CAST(c.Frequency AS VARCHAR(4)) END 
		FROM Credentials c
		WHERE DeletedDate Is Null And IsCurrent = 1 
		ORDER BY Credential;
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName, Status
	FROM Staff
	WHERE DeletedDate IS NULL AND DateLeft IS NULL
	ORDER BY LastName, FirstName, MI;

proc_GetCurrentBedsAndAssignments
CREATE PROCEDURE dbo.proc_GetCurrentBedsAndAssignments
	(@EntryDate SMALLDATETIME)
	AS
	DECLARE @MaxDate SMALLDATETIME SET @MaxDate = '6/1/2079'	
	SELECT r.RoomID, r.RoomNumber, b.Description AS Bed, b.IsCrib, b.BedID, c.CampusID, s.ShelterID, c.CampusName, s.ShelterName
	FROM Beds b INNER JOIN Shelters s ON b.ShelterID = s.ShelterID AND b.DeletedDate IS NULL AND s.DeletedDate IS NULL
		INNER JOIN Campuses c ON s.CampusID = c.CampusID
		INNER JOIN RoomBedAssignments rba ON b.BedID = rba.BedID 
			AND @EntryDate BETWEEN rba.DateAssigned AND ISNULL(rba.DateMoved, @MaxDate)
		INNER JOIN Rooms r ON rba.RoomID = r.RoomID AND r.DeletedDate IS NULL
	WHERE b.ServiceStart <= @EntryDate AND ISNULL(b.ServiceEnd, @MaxDate) > @EntryDate
	UNION ALL
	SELECT RoomID = 0, RoomNumber = '', b.Description AS Bed, b.IsCrib, b.BedID, c.CampusID, s.ShelterID, c.CampusName, s.ShelterName
	FROM Beds b INNER JOIN Shelters s ON b.ShelterID = s.ShelterID AND b.DeletedDate IS NULL AND s.DeletedDate IS NULL
		INNER JOIN Campuses c ON s.CampusID = c.CampusID
		LEFT OUTER JOIN RoomBedAssignments rba ON b.BedID = rba.BedID 
			AND @EntryDate BETWEEN rba.DateAssigned AND ISNULL(rba.DateMoved, @MaxDate)
	WHERE rba.BedID IS NULL 
		AND b.ServiceStart <= @EntryDate AND ISNULL(b.ServiceEnd, @MaxDate) > @EntryDate
	ORDER BY CampusName, ShelterName, RoomNumber, Bed;
	SELECT ib.BedID, p.ParticipantID AS ClientID, LastName + ', ' + FirstName + ' ' + MI + '(P)' AS FullName, ClientTypeID, p.Sex
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
			AND @EntryDate BETWEEN i.EntryDate AND ISNULL(i.ExitDate, @MaxDate)
		INNER JOIN IntakeBeds ib ON ib.IntakeID = i.IntakeID AND ib.ClientTypeID = 1
			AND @EntryDate BETWEEN ib.DateIn AND ISNULL(ib.DateOut, @MaxDate)
	WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL
	UNION ALL
	SELECT ib.BedID, c.ChildID AS ClientID, LastName + ', ' + FirstName + ' ' + MI + '(C)' AS FullName, ClientTypeID, c.Sex
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
			AND @EntryDate BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, @MaxDate)
		INNER JOIN IntakeBeds ib ON ci.ChildIntakeID = ib.IntakeID AND ClientTypeID = 2
			AND @EntryDate BETWEEN ib.DateIn AND ISNULL(ib.DateOut, @MaxDate)
	WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL;

proc_GetDeletedAbuserAlerts
CREATE PROCEDURE dbo.proc_GetDeletedAbuserAlerts
	AS
	SELECT a.LastName + ', ' + a.FirstName + ' ' + a.MI AS Abuser,
		p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
		AlertID, a.DeletedDate, a.DeletedBy
	FROM AbuserAlerts a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
	WHERE a.DeletedDate IS NOT NULL
	ORDER BY Abuser

proc_GetDeletedAbuserIntakes
CREATE PROCEDURE dbo.proc_GetDeletedAbuserIntakes
	AS
	SELECT AbuserIntakeID, LastName + ', ' + FirstName + ' ' + MI AS Abuser, EntryDate, ai.DeletedDate, ai.DeletedBy
	FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
	WHERE ai.DeletedDate IS NOT NULL
	ORDER BY Abuser

proc_GetDeletedAbusers
CREATE PROCEDURE dbo.proc_GetDeletedAbusers
	AS
	SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB, DeletedBy, DeletedDate
	FROM Abusers WHERE DeletedDate IS NOT NULL ORDER BY FullName

proc_GetDeletedAliases
CREATE PROCEDURE dbo.proc_GetDeletedAliases
	AS
	SELECT AliasID, a.LastName + ', ' + a.FirstName + ' ' + a.MI AS Alias,
		p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant, a.DeletedDate, a.DeletedBy
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID
	WHERE a.DeletedDate IS NOT NULL
	ORDER BY Alias

proc_GetDeletedAssessments
CREATE PROCEDURE dbo.proc_GetDeletedAssessments
	AS
	SELECT a.AssessmentID, LastName + ', ' + FirstName + ' ' + MI AS Participant,
		a.AssessmentDate, a.DeletedBy, a.DeletedDate
	FROM Assessments a INNER JOIN Intakes i ON a.IntakeID = i.IntakeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE a.DeletedDate IS NOT NULL
	ORDER BY Participant

proc_GetDeletedCalls
CREATE PROCEDURE dbo.proc_GetDeletedCalls
	AS
	SELECT CallID, LastName + ', ' + FirstName + ' ' + MI AS Caller, CallDate, DeletedDate, DeletedBy,
		CallType = CASE
		WHEN CallTypeID = 1 THEN 'Crisis'
		WHEN CallTypeID = 2 THEN 'Info/Referral'
		WHEN CallTypeID = 3 THEN 'Both'
		WHEN CallTypeID = 4 THEN 'Not Reportable' END
	FROM Calls
	WHERE DeletedDate IS NOT NULL
	ORDER BY CallDate

proc_GetDeletedChildAliases
CREATE PROCEDURE dbo.proc_GetDeletedChildAliases
	AS
	SELECT AliasID, ca.LastName + ', ' + ca.FirstName + ' ' + ca.MI AS Alias,
		c.LastName + ', ' + c.FirstName + ' ' + c.MI AS Child, ca.DeletedDate, ca.DeletedBy
	FROM ChildAliases ca INNER JOIN Children c ON ca.ChildID = c.ChildID
	WHERE ca.DeletedDate IS NOT NULL
	ORDER BY Alias

proc_GetDeletedChildIntakes
CREATE PROCEDURE dbo.proc_GetDeletedChildIntakes
	AS
	SELECT ci.ChildIntakeID, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS Child, ci.EntryDate, ShelterName, ci.DeletedDate, ci.DeletedBy
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN Shelters s ON s.ShelterID = i.ShelterID
	WHERE ci.DeletedDate IS NOT NULL
	ORDER BY Child

proc_GetDeletedChildren
CREATE PROCEDURE dbo.proc_GetDeletedChildren
	AS
	SELECT ChildID, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS Child,
		p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant, c.DeletedDate, c.DeletedBy
	FROM Children c INNER JOIN Participants p ON c.ParticipantID = p.ParticipantID
	WHERE c.DeletedDate IS NOT NULL
	ORDER BY Child

proc_GetDeletedCommunityMembers
CREATE PROCEDURE proc_GetDeletedCommunityMembers
	AS
	SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DeletedBy, DeletedDate
	FROM CommunityMembers WHERE DeletedDate IS NOT NULL ORDER BY FullName

proc_GetDeletedCredentials
CREATE PROCEDURE dbo.proc_GetDeletedCredentials
	AS
	SELECT CredentialID, [Credential], Academic = CASE WHEN IsSubject = 0 THEN 'No' WHEN IsSubject = 1 THEN 'Yes' END,
		DeletedDate, DeletedBy
	FROM Credentials WHERE DeletedDate IS NOT NULL
	ORDER BY [Credential]

proc_GetDeletedEmergencyContacts
CREATE PROCEDURE dbo.proc_GetDeletedEmergencyContacts
	AS
	SELECT EmerContactID, ContactName, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant, e.DeletedDate, e.DeletedBy
	FROM EmerContacts e INNER JOIN Participants p ON e.ParticipantID = p.ParticipantID
	WHERE e.DeletedDate IS NOT NULL
	ORDER BY Participant

proc_GetDeletedGrantors
CREATE PROCEDURE dbo.proc_GetDeletedGrantors
	AS
	SELECT GrantorID, Grantor, DeletedDate, DeletedBy
	FROM Grantors
	WHERE DeletedDate IS NOT NULL
	ORDER BY Grantor

proc_GetDeletedGrants
CREATE PROCEDURE dbo.proc_GetDeletedGrants
	AS
	SELECT GrantID, Grantor, ContractNumber, GrantStart, GrantEnd, g.DeletedDate, g.DeletedBy
	FROM Grants g INNER JOIN Grantors gg ON g.GrantorID = gg.GrantorID
	WHERE g.DeletedDate IS NOT NULL
	ORDER BY Grantor

proc_GetDeletedInfoReleases
CREATE PROCEDURE dbo.proc_GetDeletedInfoReleases
	AS
	SELECT ir.ReleaseID, LastName + ', ' + FirstName + ' ' + MI AS Participant,
		rt.ReleaseType, ir.FromDate, ir.ToDate
	FROM InfoReleases ir INNER JOIN ReleaseTypes rt ON ir.ReleaseTypeID = rt.ReleaseTypeID
		INNER JOIN Participants p ON ir.ParticipantID = p.ParticipantID
	WHERE ir.DeletedDate IS NOT NULL
	ORDER BY Participant;

proc_GetDeletedIntakes
CREATE PROCEDURE dbo.proc_GetDeletedIntakes
	AS
	SELECT IntakeID, LastName + ', ' + FirstName + ' ' + MI AS Participant, EntryDate, IntakeType, i.DeletedDate, i.DeletedBy
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
	WHERE i.DeletedDate IS NOT NULL
	ORDER BY Participant				

proc_GetDeletedInterventions
CREATE PROCEDURE dbo.proc_GetDeletedInterventions
	AS
	SELECT i.InterventionID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName, 
		InterventionDate = CASE
			WHEN s.SessionDate IS NULL THEN 'No Service'
			ELSE CONVERT(VARCHAR(25), s.SessionDate, 101) END,
		i.DeletedBy, i.DeletedDate
	FROM Interventions i INNER JOIN Participants p ON i.ClientID = p.ParticipantID AND i.ClientTypeID = 1
		LEFT OUTER JOIN Sessions s ON i.SessionID = s.SessionID
	WHERE i.DeletedDate IS NOT NULL
	UNION ALL
	SELECT i.InterventionID, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS FullName,
		InterventionDate = CASE
			WHEN s.SessionDate IS NULL THEN 'No Service'
			ELSE CONVERT(VARCHAR(25), s.SessionDate, 101) END,
		i.DeletedBy, i.DeletedDate
	FROM Interventions i INNER JOIN CommunityMembers cm ON i.ClientID = cm.MemberID AND i.ClientTypeID = 4
		LEFT OUTER JOIN Sessions s ON i.SessionID = s.SessionID
	WHERE i.DeletedDate IS NOT NULL
	ORDER BY FullName

proc_GetDeletedNotes
CREATE PROCEDURE dbo.proc_GetDeletedNotes
	AS
	SELECT NoteID, p.LastName + ', ' + p.FirstName + ' ' + p.MI + ' (P)' AS Client, NoteDate, 
		[Subject], n.DeletedDate, n.DeletedBy
	FROM Notes n INNER JOIN Participants p ON n.ClientID = p.ParticipantID AND n.ClientTypeID = 1
	WHERE n.DeletedDate IS NOT NULL
	UNION ALL
	SELECT NoteID, c.LastName + ', ' + c.FirstName + ' ' + c.MI + ' (C)' AS Client, NoteDate, 
		[Subject], n.DeletedDate, n.DeletedBy
	FROM Notes n INNER JOIN Children c ON n.ClientID = c.ChildID AND n.ClientTypeID = 2
	WHERE n.DeletedDate IS NOT NULL
	UNION ALL
	SELECT NoteID, a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (A)' AS Client, NoteDate, 
		[Subject], n.DeletedDate, n.DeletedBy
	FROM Notes n INNER JOIN Abusers a ON n.ClientID = a.AbuserID AND n.ClientTypeID = 3
	WHERE n.DeletedDate IS NOT NULL
	ORDER BY Client

proc_GetDeletedParticipantFiles
CREATE PROCEDURE dbo.proc_GetDeletedParticipantFiles
	AS
	SELECT FileID, ShortFileName, p.LastName + ', ' + p.FirstName AS Participant, pf.DeletedBy, pf.DeletedDate
	FROM ParticipantFiles pf INNER JOIN Participants p ON pf.ParticipantID = p.ParticipantID
	WHERE pf.DeletedDate IS NOT NULL
	ORDER BY ShortFileName

proc_GetDeletedParticipants
CREATE PROCEDURE dbo.proc_GetDeletedParticipants
	AS
	SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS Participant, DeletedDate, DeletedBy
	FROM Participants
	WHERE DeletedDate IS NOT NULL
	ORDER BY Participant

proc_GetDeletedPresentations
CREATE PROCEDURE dbo.proc_GetDeletedPresentations
	AS
	SELECT PresentationID, Location, PresentationDate, DeletedDate, DeletedBy
	FROM Presentations
	WHERE DeletedDate IS NOT NULL
	ORDER BY PresentationDate

proc_GetDeletedQuestionnaires
CREATE PROCEDURE dbo.proc_GetDeletedQuestionnaires
	AS
	SELECT QuestionnaireID, SurveyName, CompletedDate, ControlNumber, q.DeletedDate, q.DeletedBy
	FROM Questionnaires q INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
	WHERE q.DeletedDate IS NOT NULL
	ORDER BY SurveyName, CompletedDate

proc_GetDeletedReferrals
CREATE PROCEDURE dbo.proc_GetDeletedReferrals
	AS
	SELECT ReferralID, p.LastName + ', ' + p.FirstName + ' ' + p.MI + ' (P)' AS Client,
		ReferralType, ReferralDate,  r.DeletedDate, r.DeletedBy
	FROM Participants p INNER JOIN Referrals r ON p.ParticipantID = r.ClientID AND r.ClientTypeID = 1
		INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
	WHERE r.DeletedDate IS NOT NULL
	UNION ALL
	SELECT ReferralID, c.LastName + ', ' + c.FirstName + ' ' + c.MI + ' (C)' AS Client,
		ReferralType, ReferralDate,  r.DeletedDate, r.DeletedBy
	FROM Children c INNER JOIN Referrals r ON c.ChildID = r.ClientID AND r.ClientTypeID = 2
		INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
	WHERE r.DeletedDate IS NOT NULL
	UNION ALL
	SELECT ReferralID, a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (A)' AS Client,
		ReferralType, ReferralDate,  r.DeletedDate, r.DeletedBy
	FROM Abusers a INNER JOIN Referrals r ON a.AbuserID = r.ClientID AND r.ClientTypeID = 3
		INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
	WHERE r.DeletedDate IS NOT NULL
	ORDER BY ReferralDate

proc_GetDeletedReportNarratives
CREATE PROCEDURE dbo.proc_GetDeletedReportNarratives
	AS
	SELECT NarrativeID, ReportNumber, ReportDate, Item, DeletedBy, DeletedDate
	FROM ReportNarratives
	WHERE DeletedDate IS NOT NULL
	ORDER BY ReportNumber, ReportDate

proc_GetDeletedServiceSessions
CREATE PROCEDURE dbo.proc_GetDeletedServiceSessions
	AS
	SELECT ss.SessionID, ServiceName, SessionDate, SessionHours, ss.DeletedDate, ss.DeletedBy
	FROM Services s INNER JOIN [Sessions] ss ON s.ServiceID = ss.ServiceID
		INNER JOIN ClientSessions cs ON ss.SessionID = cs.SessionID
	WHERE ss.DeletedDate IS NOT NULL
	ORDER BY SessionDate

proc_GetDeletedStaff
CREATE PROCEDURE dbo.proc_GetDeletedStaff
	AS
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS StaffMember, Title, DeletedDate, DeletedBy
	FROM Staff
	WHERE DeletedDate IS NOT NULL
	ORDER BY StaffMember

proc_GetDeletedSurveys
CREATE PROCEDURE dbo.proc_GetDeletedSurveys
	AS
	SELECT SurveyID, SurveyName, DeletedDate, DeletedBy
	FROM Surveys
	WHERE DeletedDate IS NOT NULL
	ORDER BY SurveyName

proc_GetDeletedTrainingSessions
CREATE PROCEDURE dbo.proc_GetDeletedTrainingSessions
	AS
	SELECT ts.SessionID, c.Credential AS Subject, SessionDate, SessionHours, ts.DeletedDate, ts.DeletedBy
	FROM TrainingSessions ts INNER JOIN Credentials c ON ts.SubjectID = c.CredentialID
	WHERE ts.DeletedDate IS NOT NULL
	ORDER BY SessionDate

proc_GetDeletedVolunteerActivities
CREATE PROCEDURE dbo.proc_GetDeletedVolunteerActivities
	AS
	SELECT vas.ActivityID, LastName + ', ' + FirstName AS Volunteer, Activity, ActivityDate, Hours, vas.DeletedDate, vas.DeletedBy
	FROM Staff s INNER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
		INNER JOIN VolunteerActivities vas ON va.ActivityID = vas.ActivityID
	WHERE vas.DeletedDate IS NOT NULL
	ORDER BY ActivityDate, Volunteer

proc_GetDelinquentData
CREATE PROCEDURE dbo.proc_GetDelinquentData
	AS
	DECLARE @MaxDaysToComplete INT, @MaxDaysInactive INT, @MaxDaysSinceCall INT
	SET @MaxDaysToComplete = (SELECT TOP 1 MaxDaysToComplete FROM zsSettings);
	SET @MaxDaysInactive = (SELECT TOP 1 MaxDaysInactive FROM zsSettings);
	SET @MaxDaysSinceCall = (SELECT TOP 1 MaxDaysSinceCall FROM zsSettings);
	-- Overdue entry/exit data
	SELECT ShelterName, LastName + ', ' + FirstName + ' ' + MI As FullName, IntakeID, DATEDIFF(day, EntryDate, getdate()) As Days
	FROM Participants p INNER JOIN Intakes i On p.ParticipantID = i.ParticipantID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE EntryDataComplete = 0 AND DATEDIFF(day, EntryDate, getdate()) > @MaxDaysToComplete 
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
	UNION
	SELECT ShelterName, LastName + ', ' + FirstName + ' ' + MI As FullName, IntakeID, DATEDIFF(day, ExitDate, getdate()) As Days
	FROM Participants p INNER JOIN Intakes i On p.ParticipantID = i.ParticipantID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE ExitDate IS NOT NULL AND ExitDataComplete = 0 AND DATEDIFF(day, ExitDate, getdate()) > @MaxDaysToComplete
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
	ORDER BY ShelterName, Days DESC;
	-- Over 120 days w/o waiver
	SELECT ShelterName, LastName + ', ' + FirstName + ' ' + MI As FullName, IntakeID, DATEDIFF(day, EntryDate, IsNull(ExitDate, getdate())) As Days
	FROM Participants p INNER JOIN Intakes i On p.ParticipantID = i.ParticipantID
		INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE  IntakeTypeID = 1 AND DATEDIFF(day, EntryDate, IsNull(ExitDate, getdate())) > 120 AND ExtensionWavier = 0
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
	ORDER BY ShelterName, Days DESC;
	-- Inactive non-residents
	SELECT ShelterName, LastName + ', ' + FirstName + ' ' + MI AS FullName, i.IntakeID, 
		Max(s.SessionDate) AS LastService, DateDiff(day, Max(s.SessionDate), getdate()) AS DaysSinceLastService
	FROM 
		Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN Shelters sh ON i.ShelterID = sh.ShelterID
		INNER JOIN ClientSessions cs ON i.IntakeID = cs.IntakeID And cs.ClientTypeID = 1
		INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
	WHERE IntakeTypeID = 4 And i.ExitDate IS NULL And i.DeletedDate IS NULL And p.DeletedDate IS NULL
	GROUP BY ShelterName, LastName, FirstName, MI, i.IntakeID
	HAVING DateDiff(day, Max(s.SessionDate), getdate()) > @MaxDaysInactive
	ORDER BY ShelterName, DaysSinceLastService DESC;
	-- Unlinked calls where 'Shelter Provided'
	SELECT ShelterName, c.CallID, LastName + ', ' + FirstName AS CallerName, CallDate
	FROM ShelterRequests sr INNER JOIN Calls c ON sr.CallID = c.CallID
		INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
		LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
	WHERE sr.RequestOutcomeID IN (2, 3) AND ic.IntakeID IS NULL AND DateDiff(day, CallDate, getdate()) > @MaxDaysSinceCall
		AND c.DeletedDate IS NULL
	ORDER BY CallDate;

proc_GetEmerContact
CREATE PROCEDURE dbo.proc_GetEmerContact  
	(@EmerContactID INT)  
	AS  
	SELECT TOP 1 *  
	FROM EmerContacts  
	WHERE EmerContactID = @EmerContactID  

proc_GetGrant
CREATE PROCEDURE dbo.proc_GetGrant
	(@GrantID INT)
	AS
	SELECT g.GrantorID, g.ContractNumber, g.GrantStart, g.GrantEnd, g.Prorate,
		g.CreatedBy, g.CreatedDate, g.ModifiedBy, g.ModifiedDate,
		gt.TargetTypeID, gt.TargetID
	FROM Grants g LEFT OUTER JOIN GrantTargets gt ON g.GrantID = gt.GrantID
	WHERE g.GrantID = @GrantID;
	SELECT gs.SurveyID
	FROM GrantSurveys gs INNER JOIN Surveys s ON gs.SurveyID = s.SurveyID
	WHERE GrantID = @GrantID AND s.DeletedDate IS NULL

proc_GetGrantorLists
CREATE PROCEDURE dbo.proc_GetGrantorLists
AS
	SELECT SurveyID, Survey = CASE WHEN IsCurrent = 1 THEN SurveyName ELSE '*' + SurveyName END,
		IsCurrent
	FROM Surveys
	WHERE DeletedDate IS NULL
	ORDER BY SurveyName;
	SELECT g.GrantorID, g.Grantor, g.CreatedBy, g.CreatedDate, g.ModifiedBy, g.ModifiedDate
	FROM Grantors g
	WHERE DeletedDate IS NULL
	ORDER BY Grantor;
	SELECT *
	FROM GrantorServices gs
	WHERE DeletedDate IS NULL
	ORDER BY IsCurrent DESC, GrantorID, GrantorService;
	SELECT gg.Grantor, g.GrantorID, g.GrantID, g.GrantStart, g.GrantEnd, g.ContractNumber
	FROM Grants g INNER JOIN Grantors gg ON g.GrantorID = gg.GrantorID
	WHERE g.DeletedDate IS NULL and gg.DeletedDate IS NULL
	ORDER BY g.GrantStart, gg.Grantor;

proc_GetInfoRelease
CREATE PROCEDURE dbo.proc_GetInfoRelease
	(@ReleaseID INT)
	AS
	SELECT *
	FROM InfoReleases ir INNER JOIN ReleaseEntities re ON ir.ReleaseID = re.ReleaseID
	WHERE ir.ReleaseID = @ReleaseID

proc_GetInfoReleaseLookups
CREATE PROCEDURE dbo.proc_GetInfoReleaseLookups
	AS
	SELECT r.ReleaseTypeID, r.ReleaseType
	FROM ReleaseTypes r
	WHERE r.DeletedDate IS NULL
	ORDER BY ReleaseType;
	SELECT ie.EntityID, ie.Entity
	FROM InfoEntities ie
	WHERE DeletedDate IS NULL
	ORDER BY Entity;

proc_GetInfoReleases
CREATE PROCEDURE dbo.proc_GetInfoReleases
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByEventDate BIT)
	AS
	IF @ByEventDate = 1
		BEGIN
			SELECT ir.ReleaseID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
				r.ReleaseType, ir.FromDate, ir.ToDate
			FROM InfoReleases ir INNER JOIN ReleaseTypes r ON ir.ReleaseTypeID = r.ReleaseTypeID
				INNER JOIN Participants p ON ir.ParticipantID = p.ParticipantID
			WHERE (ir.FromDate BETWEEN @FromDate AND @ToDate
				OR ir.ToDate BETWEEN @FromDate AND @ToDate)
				AND ir.DeletedDate IS NULL
			ORDER BY ir.FromDate
		END
	ELSE
		BEGIN
			SELECT ir.ReleaseID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
				r.ReleaseType, ir.FromDate, ir.ToDate
			FROM InfoReleases ir INNER JOIN ReleaseTypes r ON ir.ReleaseTypeID = r.ReleaseTypeID
				INNER JOIN Participants p ON ir.ParticipantID = p.ParticipantID
			WHERE ir.ModifiedDate BETWEEN @FromDate AND @ToDate
				AND ir.DeletedDate IS NULL
			ORDER BY ir.FromDate			
		END

proc_GetIntake
-- Change the GetIntake procedure to also retrieve related values in the IntakeVictimType table
CREATE PROCEDURE dbo.proc_GetIntake  
	(@IntakeID INT)  
	AS
	DECLARE @MaxDate SMALLDATETIME SET @MaxDate = '6/1/2079'
	DECLARE @ParticipantID INT, @IntakeTypeID INT
	SET @IntakeTypeID = (SELECT TOP 1 IntakeTypeID FROM Intakes WHERE IntakeID = @IntakeID)
	-- Participant data
	SET @ParticipantID = (SELECT TOP 1 ParticipantID FROM Intakes WHERE IntakeID = @IntakeID);
	SELECT ParticipantID, LastName, FirstName, MI, Sex FROM Participants WHERE ParticipantID = @ParticipantID;
	-- Basic intake data and Current Room, Bed, if any, and call, if any
	SELECT i.*, ISNULL(b.Description, 'Not Assigned') AS Bed, ISNULL(r.RoomNumber, '') AS Room, 
		c.CallID, c.ShelterID AS HotlineShelterID, c.CallDate, c.WalkIn, ii.InterventionID  
	FROM Intakes i LEFT OUTER JOIN IntakeBeds ib ON i.IntakeID = ib.IntakeID AND ib.ClientTypeID = 1
			AND ib.DateIn <= GETDATE() AND ISNULL(ib.DateOut, @MaxDate) > GETDATE()
		LEFT OUTER JOIN Beds b ON ib.BedID = b.BedID
		LEFT OUTER JOIN RoomBedAssignments rba ON rba.BedID = b.BedID 
			AND rba.DateAssigned <= GETDATE() AND ISNULL(rba.DateMoved, @MaxDate) > GETDATE() 		
		LEFT OUTER JOIN Rooms r on rba.RoomID = r.RoomID
		LEFT OUTER JOIN IntakeCalls ic ON ic.IntakeID = i.IntakeID
		LEFT OUTER JOIN Calls c ON ic.CallID = c.CallID
		LEFT OUTER JOIN Interventions ii ON ii.IntakeID = i.IntakeID 
	WHERE i.IntakeID = @IntakeID;
	-- Linked Origin Intake, if any
	SELECT TOP 1 li.OriginIntakeID, s.ShelterName AS OriginShelter, i.EntryDate AS OriginEntryDate
		FROM LinkedIntakes li INNER JOIN Intakes i ON li.OriginIntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
		WHERE li.ParticipantID = @ParticipantID AND GainingIntakeID = @IntakeID;	
	-- Intake Staff:  Name and role	
	SELECT ist.StaffID, s.LastName + ', ' + s.FirstName AS StaffName, ist.StaffRole
		FROM IntakeStaff ist INNER JOIN Staff s ON ist.StaffID = s.StaffID
		WHERE ist.IntakeID = @IntakeID;
	-- Intake Phases
	SELECT p.PhaseID, p.PhaseName, p.ProjectedLength, ip.BeginDate, ip.ProjectedEnd, ip.CompletedDate
	FROM Phases p LEFT OUTER JOIN IntakePhase ip ON p.PhaseID = ip.PhaseID AND ip.IntakeID = @IntakeID
	WHERE p.DeletedDate IS NULL AND p.IsCurrent = 1 AND p.IntakeTypeID = @IntakeTypeID
	ORDER BY p.Sequence, p.PhaseName;
	-- Intake Tasks
	SELECT TaskID, Task, DaysToComplete, CompletedDate =
		(SELECT TOP 1 CompletedDate FROM IntakeTasks WHERE IntakeID = @IntakeID AND TaskID = t.TaskID)
	FROM Tasks t
	WHERE DeletedDate IS NULL AND IsCurrent = 1 AND t.IntakeTypeID = @IntakeTypeID
	ORDER BY DaysToComplete;
	-- Questionnaires and Self-Sufficiency Assessments completed
	SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate
		FROM Questionnaires q INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE q.ClientTypeID = 1 AND q.IntakeID = @IntakeID AND q.DeletedDate IS NULL
	UNION ALL
	SELECT a.AssessmentID, 'SS Assessment' AS SurveyName, a.AssessmentDate
		FROM Assessments a
		WHERE IntakeID = @IntakeID AND DeletedDate IS NULL
		ORDER BY q.CompletedDate;
	-- Children
	SELECT ChildID, LastName, FirstName, MI FROM Children WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL;
	-- ChildIntakes w/Current Room, Bed		
	SELECT ci.*, ISNULL(b.Description, 'Not Assigned') AS Bed, ISNULL(r.RoomNumber, '') AS Room
		FROM ChildIntakes ci LEFT OUTER JOIN IntakeBeds ib ON ci.ChildIntakeID = ib.IntakeID AND ib.ClientTypeID = 2
				AND ib.DateIn <= GETDATE() AND ISNULL(ib.DateOut, @MaxDate) > GETDATE()
			LEFT OUTER JOIN Beds b ON ib.BedID = b.BedID
			LEFT JOIN RoomBedAssignments rba ON rba.BedID = b.BedID 
				AND rba.DateAssigned <= GETDATE() AND ISNULL(rba.DateMoved, @MaxDate) > GETDATE() 		
			LEFT JOIN Rooms r on rba.RoomID = r.RoomID
		WHERE ci.IntakeID = @IntakeID AND ci.DeletedDate IS NULL;
	-- Child Absences
	SELECT ca.ChildIntakeID, ca.DateOut, ca.DateReturn
		FROM ChildAbsences ca
		WHERE ca.ChildIntakeID IN
			(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID AND DeletedDate IS NULL)
		ORDER BY ChildIntakeID, ca.DateOut;
	-- Pets
	SELECT PetID, p.PetTypeID, x.PetType, p.Name, p.Breed, p.IsAbused, p.IsVaccinated, p.RetainedOnExit
	FROM Pets p INNER JOIN xPetType x ON p.PetTypeID = x.PetTypeID
	WHERE IntakeID = @IntakeID
	ORDER BY p.PetTypeID, Name;
	-- VictimTypes
	SELECT VictimTypeID
	FROM IntakeVictimType
	WHERE IntakeID = @IntakeID

proc_GetIntakeQuestionnaires
CREATE PROCEDURE dbo.proc_GetIntakeQuestionnaires
	(@IntakeID INT)
	AS
	SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate
	FROM Questionnaires q INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
	WHERE q.ClientTypeID = 1 AND q.IntakeID = @IntakeID AND q.DeletedDate IS NULL
	UNION ALL
	SELECT a.AssessmentID, 'SS Assessment' AS SurveyName, a.AssessmentDate
	FROM Assessments a
	WHERE IntakeID = @IntakeID AND DeletedDate IS NULL
	ORDER BY q.CompletedDate

proc_GetIntakeServices
CREATE PROCEDURE dbo.proc_GetIntakeServices
	(@IntakeID INT)
	AS
	SELECT s.SessionID, Program, SessionDate, ServiceName, IsNULL(Focus, '') AS Focus, SessionHours, 
		ISNULL(LastName + ', ' + FirstName, '') AS StaffName, IsGroup,
		((DATEDIFF(day, i.EntryDate, s.SessionDate) - DATEPART(dw, s.SessionDate))/7) + 1 AS Week
	FROM Intakes i INNER JOIN ClientSessions cs ON i.IntakeID = cs.IntakeID And cs.ClientTypeID = 1
		INNER JOIN Sessions s ON cs.SessionID = s.SessionID
		INNER JOIN Services ON s.ServiceID = Services.ServiceID
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		LEFT OUTER JOIN Focus f ON s.FocusID = f.FocusID
		LEFT OUTER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
		LEFT OUTER JOIN Staff ON ss.StaffID = Staff.StaffID
	WHERE cs.IntakeID = @IntakeID
	ORDER BY IsGroup, SessionDate, SessionID

proc_GetIntakeServicesAndReferrals
CREATE PROCEDURE dbo.proc_GetIntakeServicesAndReferrals
	(@IntakeID INT, @ClientType INT)
	AS
	IF @ClientType = 1
		BEGIN
		SELECT s.SessionID, Program, SessionDate, ServiceName, IsNULL(Focus, '') AS Focus, SessionHours, 
			ISNULL(LastName + ', ' + FirstName, '') AS StaffName, IsGroup,
			((DATEDIFF(day, i.EntryDate, s.SessionDate) - DATEPART(dw, s.SessionDate))/7) + 1 AS Week
		FROM Intakes i INNER JOIN ClientSessions cs ON i.IntakeID = cs.IntakeID And cs.ClientTypeID = 1
			INNER JOIN Sessions s ON cs.SessionID = s.SessionID
			INNER JOIN Services ON s.ServiceID = Services.ServiceID
			INNER JOIN Programs p ON s.ProgramID = p.ProgramID
			LEFT OUTER JOIN Focus f ON s.FocusID = f.FocusID
			LEFT OUTER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
			LEFT OUTER JOIN Staff ON ss.StaffID = Staff.StaffID
		WHERE cs.IntakeID = @IntakeID AND i.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
		ORDER BY IsGroup, SessionDate, SessionID;
		SELECT r.ReferralID, ReferralType, ReferralDate, Agency, NumberReferrals, LastName + ', ' + FirstName AS StaffName
		FROM Intakes i INNER JOIN Referrals r ON i.IntakeID = r.IntakeID AND r.ClientTypeID = 1
			INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
			LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
			LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
		WHERE r.IntakeID = @IntakeID AND r.DeletedDate IS NULL AND i.DeletedDate IS NULL
		ORDER BY ReferralDate
		END
	ELSE
		BEGIN
        SELECT s.SessionID, Program, SessionDate, ServiceName, ISNULL(Focus, '') AS Focus, SessionHours,
            ISNULL(LastName + ', ' + FirstName, '') AS StaffName, IsGroup,
            ((DATEDIFF(day, ci.EntryDate, s.SessionDate) - DATEPART(dw, s.SessionDate))/7) + 1 AS Week	
        FROM ChildIntakes ci INNER JOIN ClientSessions cs ON ci.ChildIntakeID = cs.IntakeID AND cs.ClientTypeID = 2
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN Services svs ON s.ServiceID = svs.ServiceID
            INNER JOIN Programs p ON s.ProgramID = p.ProgramID
            LEFT OUTER JOIN Focus f ON s.FocusID = f.FocusID
            LEFT OUTER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
            LEFT OUTER JOIN Staff st ON ss.StaffID = st.StaffID
        WHERE cs.IntakeID = @IntakeID AND ci.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        ORDER BY IsGroup, SessionDate, cs.SessionID;
        SELECT r.ReferralID, ReferralType, ReferralDate, Agency, NumberReferrals, LastName + ', ' + FirstName AS StaffName
        FROM ChildIntakes ci INNER JOIN Referrals r ON ci.ChildIntakeID = r.IntakeID AND r.ClientTypeID = 2
            INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
            LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
        WHERE r.IntakeID = @IntakeID AND r.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        ORDER BY ReferralDate
        END

proc_GetIntervention
CREATE PROCEDURE dbo.proc_GetIntervention
	(@InterventionID INT)
	AS
	SELECT i.ClientID, i.ClientTypeID, i.IntakeID, ISNULL(p.LastName + ', ' + p.FirstName + ' ' + p.MI, '') AS ParticipantName,
		ISNULL(cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI, '') AS MemberName,
		i.PoliceReport, i.PreviousReport, i.DVArrestClient, i.DVArrestBatterer, i.PreviousArrestClient, i.PreviousArrestBatterer,
		i.CurrentProtectionOrder, i.PreviousProtectionOrder, i.EmergencyMedClient, i.EmergencyMedBatterer, i.LawAgencyID, i.Abuser, i.AbuserRelationshipID,
		i.Address, i.City, i.State, i.Zip, i.Phone, i.CountyID, i.ReservationID, i.LocationID, i.Advocacy,
		s.SessionID, s.SessionDate, s.SessionHours, s.NumberStaff, s.ServiceID, s.ProgramID, ss.StaffID, ii.EntryDate,
		i.ModifiedBy, i.ModifiedDate, i.CreatedBy, i.CreatedDate
	FROM Interventions i 
		INNER JOIN Sessions s ON i.SessionID = s.SessionID
		LEFT OUTER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
		LEFT OUTER JOIN Intakes ii ON i.IntakeID = ii.IntakeID
		LEFT OUTER JOIN Participants p ON i.ClientID = p.ParticipantID AND i.ClientTypeID = 1
		LEFT OUTER JOIN CommunityMembers cm ON i.ClientID = cm.MemberID AND i.ClientTypeID = 4
	WHERE i.InterventionID = @InterventionID

proc_GetInterventionLists
CREATE PROCEDURE dbo.proc_GetInterventionLists
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	-- All Participants
	SELECT ParticipantID, FullName = CASE
		WHEN ReturnStatusID = 1 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [A]'
		WHEN ReturnStatusID = 2 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [B]'
		WHEN ReturnStatusID = 3 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [C]'
		WHEN ReturnStatusID = 4 THEN LastName + ', ' + FirstName + ' ' + MI + ' (' + Convert(VarChar(50), DOB, 110) + ')   [D]'
		END
	FROM Participants 
	WHERE DeletedDate IS NULL
	UNION
	SELECT a.ParticipantID, FullName = CASE
		WHEN ReturnStatusID = 1 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [A]' 
		WHEN ReturnStatusID = 2 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [B]'
		WHEN ReturnStatusID = 3 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [C]'
		WHEN ReturnStatusID = 4 THEN a.LastName + ', ' + a.FirstName + ' ' + a.MI + ' (' + Convert(VarChar(50), DOB, 110) + ')    [D]'
		END
	FROM Aliases a INNER JOIN Participants p ON a.ParticipantID = p.ParticipantID 
	WHERE a.DeletedDate IS NULL And p.DeletedDate IS NULL
	ORDER BY FullName;
	-- All Community Members
	SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM CommunityMembers
	WHERE DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI;
	-- Law Enforcement Agencies
	SELECT AgencyID, Agency
	FROM xLawEnforcementAgency
	WHERE DeletedDate IS NULL
	ORDER BY Agency;
	-- Services
	SELECT ServiceID, 
		Service = CASE WHEN DiscontinuedDate IS NULL THEN ServiceName ELSE '*' + ServiceName END,
		IsCurrent = CASE WHEN DiscontinuedDate IS NULL THEN 1 ELSE 0 END, IsGroup, ByPhone
	FROM [Services]
	WHERE DeletedDate IS NULL
	ORDER BY ServiceName
	-- Programs
	SELECT p.ProgramID, Program = CASE WHEN IsCurrent = 1 THEN Program ELSE '*' + Program END, IsCurrent, ServiceID
	FROM Programs p INNER JOIN ProgramServices ps ON p.ProgramID = ps.ProgramID
	WHERE DeletedDate IS NULL
	ORDER BY p.Program
	-- Interventions
	SELECT i.InterventionID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
		ClientType = 'Participant', s.SessionDate
	FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
		INNER JOIN Participants p ON i.ClientID = p.ParticipantID AND i.ClientTypeID = 1
	WHERE s.SessionDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
	UNION ALL
	SELECT i.InterventionID, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS FullName,
		ClientType = 'Community Member', s.SessionDate
	FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
		INNER JOIN CommunityMembers cm ON i.ClientID = cm.MemberID AND i.ClientTypeID = 4
	WHERE s.SessionDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
	ORDER BY s.SessionDate
	-- Intake Data for current clients, including exits from within one month
	SELECT ParticipantID, i.IntakeID, i.EntryDate AS EntryDate, i.ExitDate,
		CONVERT(VARCHAR(50), i.EntryDate, 110) + ' - ' + CASE WHEN i.ExitDate IS NULL THEN 'Present'
			ELSE CONVERT(VARCHAR(50), i.ExitDate, 110)  END + ' (' + ShelterName + ')' AS IntakeData    
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.DeletedDate IS NULL AND ParticipantID IN
		(SELECT p.ParticipantID
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID  
		WHERE (p.DeletedDate IS NULL) AND 
		(i.ExitDate IS NULL OR -- Still present
		(i.ExitDate >= DATEADD(MONTH, -1, GETDATE())))) -- Exit within one month
	ORDER BY i.EntryDate DESC

proc_GetInterventions
CREATE PROCEDURE dbo.proc_GetInterventions
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByActivityDate BIT)
	AS
		IF @ByActivityDate = 1
			SELECT i.InterventionID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
				ClientType = 'Participant', s.SessionDate
			FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
				INNER JOIN Participants p ON i.ClientID = p.ParticipantID AND i.ClientTypeID = 1
			WHERE s.SessionDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
			UNION ALL
			SELECT i.InterventionID, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS FullName,
				ClientType = 'Community Member', s.SessionDate
			FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
				INNER JOIN CommunityMembers cm ON i.ClientID = cm.MemberID AND i.ClientTypeID = 4
			WHERE s.SessionDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
			ORDER BY s.SessionDate
		ELSE
			SELECT i.InterventionID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
				ClientType = 'Participant', s.SessionDate
			FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
				INNER JOIN Participants p ON i.ClientID = p.ParticipantID AND i.ClientTypeID = 1
			WHERE i.ModifiedDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
			UNION ALL
			SELECT i.InterventionID, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS FullName,
				ClientType = 'Community Member', s.SessionDate
			FROM Interventions i INNER JOIN Sessions s ON i.SessionID = s.SessionID
				INNER JOIN CommunityMembers cm ON i.ClientID = cm.MemberID AND i.ClientTypeID = 4
			WHERE i.ModifiedDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL
			ORDER BY s.SessionDate;

proc_GetLookupsNormal
CREATE PROCEDURE dbo.proc_GetLookupsNormal 
	AS 
	SELECT CallTypeID, CallType FROM xCallType; 
	SELECT CitizenshipID, Citizenship FROM xCitizenship; 
	SELECT ClientTypeID, ClientType FROM xClientType; 
	SELECT CountyID, County FROM xCounty; 
	SELECT CourtOutcomeID, CourtOutcome FROM xCourtOutcome; 
	SELECT EmploymentID, Employment FROM xEmployment ORDER BY EmploymentID; 
	SELECT HousingTypeID, HousingType FROM xHousingType; 
	SELECT IntakeTypeID, IntakeType FROM xIntakeType; 
	SELECT MaritalStatusID, MaritalStatus FROM xMaritalStatus; 
	SELECT RequestOutcomeID, RequestOutcome FROM xRequestOutcome; 
	SELECT ReservationID, Reservation FROM xReservation; 	
	SELECT SubstanceProblemID, SubstanceProblem FROM xSubstanceProblem; 
	SELECT ReturnStatusID, ReturnStatus FROM xReturnStatus;
	SELECT LanguageID, Language FROM xLanguage; 
	SELECT LocationID, Location FROM xLocation; 
	SELECT ShelterID, ShelterName FROM Shelters WHERE DeletedDate Is Null ORDER BY ShelterName;
	SELECT ServiceID, ServiceName FROM
		(SELECT ServiceID, ServiceName, IsCurrent = 1 FROM Services WHERE DiscontinuedDate IS NULL AND DeletedDate IS NULL
		UNION ALL
		SELECT ServiceID, '*' + ServiceName AS ServiceName, IsCurrent = 0 FROM Services WHERE DiscontinuedDate IS NOT NULL AND DeletedDate IS NULL)
		AS sub ORDER BY IsCurrent DESC, ServiceName;	
	SELECT ProgramID, Program FROM 
		(SELECT ProgramID, Program, IsCurrent FROM Programs WHERE IsCurrent = 1 AND DeletedDate IS NULL 
		UNION ALL
		SELECT ProgramID, '*' + Program AS Program, IsCurrent FROM Programs WHERE IsCurrent = 0 AND DeletedDate IS NULL)
		AS sub ORDER BY IsCurrent DESC, Program;	
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Staff WHERE ServiceProvider = 1 And DateLeft Is Null And DeletedDate Is Null ORDER BY LastName, FirstName, MI;
	SELECT StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName, LastName, FirstName, MI FROM Staff WHERE ServiceProvider = 1 And DateLeft Is Null And DeletedDate Is Null
		UNION ALL
		SELECT StaffID, '*' + LastName + ', ' + FirstName + ' ' + MI AS FullName, LastName, FirstName, MI FROM Staff WHERE ServiceProvider = 1 And DateLeft IS NOT NULL And DeletedDate Is Null ORDER BY LastName, FirstName, MI;
	SELECT TribeID, Tribe FROM xTribe WHERE DeletedDate Is Null ORDER BY Tribe;
	SELECT ReligionID, Religion FROM xReligion WHERE DeletedDate IS NULL ORDER BY Religion;
	SELECT VehicleID, Vehicle FROM Vehicles WHERE DeletedDate IS NULL ORDER BY Vehicle;
	SELECT PurposeID, Purpose FROM xTripPurpose WHERE DeletedDate IS NULL ORDER BY Purpose;
	SELECT TopicID, Topic FROM xTopic WHERE DeletedDate IS NULL ORDER BY Topic;
	SELECT ShelterID, ShelterName FROM Shelters WHERE Hotline = 1 And DeletedDate Is Null And IsCurrent = 1 ORDER BY ShelterName;
	SELECT PetTypeID, PetType FROM xPetType  ORDER BY PetType;
	SELECT CounselingResultID, CounselingResult FROM xCounselingResult ORDER BY CounselingResultID;
	SELECT LocationID, Location FROM xServiceLocation ORDER BY Location;

proc_GetLookupsOther
CREATE PROCEDURE dbo.proc_GetLookupsOther 
	AS 
	SELECT AbuserRelationshipID, AbuserRelationship FROM xAbuserRelationship WHERE AbuserRelationshipID < 101; 
		SELECT AbuserRelationshipID, AbuserRelationship FROM xAbuserRelationship WHERE AbuserRelationshipID > 100 ORDER BY AbuserRelationship; 
	SELECT CallSubjectID, CallSubject FROM xCallSubject WHERE CallSubjectID < 101; 
		SELECT CallSubjectID, CallSubject FROM xCallSubject WHERE CallSubjectID > 100 ORDER BY CallSubject;
	SELECT EthnicityID, Ethnicity FROM xEthnicity WHERE EthnicityID < 101 ORDER BY Ethnicity; 
		SELECT EthnicityID, Ethnicity FROM xEthnicity WHERE EthnicityID > 100 ORDER BY Ethnicity; 
	SELECT ExitDestinationID, ExitDestination FROM xExitDestination WHERE ExitDestinationID < 101; 
		SELECT ExitDestinationID, ExitDestination FROM xExitDestination WHERE ExitDestinationID > 100 ORDER BY ExitDestination; 
	SELECT ExitHousingID, ExitHousing FROM xExitHousing WHERE ExitHousingID < 101; 
		SELECT ExitHousingID, ExitHousing FROM xExitHousing WHERE ExitHousingID > 100 ORDER BY ExitHousing; 
	SELECT ExitReasonID, ExitReason FROM xExitReason WHERE ExitReasonID < 101; 
		SELECT ExitReasonID, ExitReason FROM xExitReason WHERE ExitReasonID > 100 ORDER BY ExitReason; 
	SELECT HotlineReferralID, HotlineReferral FROM xHotlineReferral WHERE HotlineReferralID < 101; 
		SELECT HotlineReferralID, HotlineReferral FROM xHotlineReferral WHERE HotlineReferralID > 100 ORDER BY HotlineReferral; 
	SELECT ReasonDeniedID, ReasonDenied FROM xReasonDenied WHERE ReasonDeniedID < 101 ORDER BY ReasonDeniedID; 
		SELECT ReasonDeniedID, ReasonDenied FROM xReasonDenied WHERE ReasonDeniedID > 100 ORDER BY ReasonDenied; 
	SELECT ReferralSourceID, ReferralSource FROM xReferralSource WHERE ReferralSourceID < 101 ORDER BY ReferralSource; 
		SELECT ReferralSourceID, ReferralSource FROM xReferralSource WHERE ReferralSourceID > 100 ORDER BY ReferralSource; 
	SELECT ReferralTypeID, ReferralType FROM xReferralType WHERE ReferralTypeID < 100 ORDER BY ReferralType; 
		SELECT ReferralTypeID, ReferralType FROM xReferralType WHERE ReferralTypeID > 99 ORDER BY ReferralType; 
	SELECT PriorResidenceID, PriorResidence FROM xPriorResidence WHERE PriorResidenceID < 101 ORDER BY PriorResidenceID; 
		SELECT PriorResidenceID, PriorResidence FROM xPriorResidence WHERE PriorResidenceID > 100 ORDER BY PriorResidence;

proc_GetNote
CREATE PROCEDURE dbo.proc_GetNote  
	(@NoteID INT)  
	AS  
	SELECT TOP 1 *  
	FROM Notes  
	WHERE NoteID = @NoteID  
	RETURN

proc_GetNotes
-- Retrieve service session notes along with regular notes
CREATE PROCEDURE dbo.proc_GetNotes
	(@ClientID INT, @ClientTypeID INT)
	AS
	SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Notes
	WHERE ClientID = @ClientID And ClientTypeID = @ClientTypeID And DeletedDate Is Null
	UNION ALL
	SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
	WHERE cs.ClientID = @ClientID AND cs.ClientTypeID = @ClientTypeID AND s.DeletedDate IS NULL	
	ORDER BY NoteType, NoteDate

proc_GetNotesIndividual
CREATE PROCEDURE dbo.proc_GetNotesIndividual
	(@ClientID INT, @ClientTypeID INT, @ClientNotes BIT, @SessionNotes BIT,
	@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	IF @ClientNotes = 1 AND @SessionNotes = 1
		BEGIN
			SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', 
				CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
			FROM Notes
			WHERE ClientID = @ClientID And ClientTypeID = @ClientTypeID And DeletedDate Is Null
				AND NoteDate BETWEEN @FromDate AND @ToDate
			UNION ALL
			SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
			FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
				INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
				INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			WHERE cs.ClientID = @ClientID AND cs.ClientTypeID = @ClientTypeID AND s.DeletedDate IS NULL
				AND s.SessionDate BETWEEN @FromDate AND @ToDate	
			ORDER BY NoteType, NoteDate
		END
	ELSE IF @ClientNotes = 1 AND @SessionNotes = 0
		BEGIN
			SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', 
				CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
			FROM Notes
			WHERE ClientID = @ClientID And ClientTypeID = @ClientTypeID And DeletedDate Is Null
				AND NoteDate BETWEEN @FromDate AND @ToDate		
			ORDER BY NoteDate		
		END
	ELSE IF @ClientNotes = 0 AND @SessionNotes = 1
		BEGIN
			SELECT NoteType = 2, s.SessionID AS NoteID, SessionDate AS NoteDate, ServiceName AS Subject, 
				Note AS NoteText, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
			FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
				INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
				INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			WHERE cs.ClientID = @ClientID AND cs.ClientTypeID = @ClientTypeID AND s.DeletedDate IS NULL	
				AND s.SessionDate BETWEEN @FromDate AND @ToDate	
			ORDER BY SessionDate		
		END

proc_GetOrganizationData
CREATE PROCEDURE dbo.proc_GetOrganizationData
	AS
	SELECT Item, ItemValue
	FROM zShelterData

proc_GetOriginIntakeData
-- Update proc_GetOriginIntakeData to retrieve related records in IntakeVictimType table
CREATE PROCEDURE dbo.proc_GetOriginIntakeData
	(@IntakeID INT)
	AS
	SELECT TOP 1 DVArrestClient, DVArrestBatterer, PreviousArrestClient, PreviousArrestBatterer,
		EmergencyMedClient, EmergencyMedBatterer, PreviousReport, PoliceReport, 
		ProtectionOrder, PreviousProtectionOrder, LastAbuseDate, AbuserRelationshipID,
		AbuseEconomic, AbusePhysical, AbuseSexual, AbuseVerbalPsychological,
		AbuseWitness, AbusedAsChild, PregnantDuringDV, MiscarriageDuringDV, LanguageID,
		CitizenshipID, MaritalStatusID, ReligionID, YearsSchooling, NumberChildren,
		Address, City, State, Zip, Phone, CountyID, LocationID, ReservationID,
		HealthStatus, PreviousMedDiscussion, MentalIllness, HIVAIDS, DevDisability,
		PhysDisability, Allergies, Pregnant, ChronicHealthCondition, Medication,
		SubstanceAbuseID, SubstanceTreatmentID, HealthComments, EmploymentID,
		IncomeEntry, SS, SSI, SSDI, TANF, GenPubAssistance, WIC, AHCCCS,
		Medicare, Medicaid, UnemploymentBenefits, EmploymentIncome, VetBenefits,
		ChildSupport, KidsCare, LowIncomeHousing, FoodStamps, CashAssistance,
		NoFinancialResources, TANF_Eligible, IncomeOther
	FROM Intakes
	WHERE IntakeID = @IntakeID;
	SELECT VictimTypeID FROM IntakeVictimType
	WHERE IntakeID = @IntakeID;

proc_GetOtherMergeCategories
CREATE PROCEDURE proc_GetOtherMergeCategories
AS
	SELECT CampusID, CampusName FROM Campuses WHERE DeletedDate IS NULL ORDER BY CampusName;
	SELECT CredentialID, Credential FROM Credentials WHERE DeletedDate IS NULL ORDER BY Credential;
	SELECT ReleaseTypeID, ReleaseType FROM ReleaseTypes WHERE DeletedDate IS NULL ORDER BY ReleaseType;
	SELECT EntityID, Entity FROM InfoEntities WHERE DeletedDate IS NULL ORDER BY Entity;
	SELECT FocusID, Focus FROM Focus WHERE DeletedDate IS NULL ORDER BY Focus;
	SELECT GoodTypeID, GoodType FROM xGoodType WHERE DeletedDate IS NULL ORDER BY GoodType;
	SELECT AgencyID, Agency FROM xLawEnforcementAgency WHERE DeletedDate IS NULL ORDER BY Agency;

proc_GetParticipantComplete
CREATE PROCEDURE dbo.proc_GetParticipantComplete
	(@ParticipantID INT)
	AS
	SELECT TOP 1 p.*, TribeID, r.*, ISNULL(pri.ReturnIssue, '') AS ReturnIssue  
	FROM Participants p LEFT OUTER JOIN TribalAffiliation  ta On (p.ParticipantID = ta.ClientID And ta.ClientTypeID = 1)
		LEFT OUTER JOIN RHBA r ON p.ParticipantID = r.ParticipantID
		LEFT OUTER JOIN ParticipantReturnIssue pri ON p.ParticipantID = pri.ParticipantID
	WHERE p.ParticipantID = @ParticipantID  And p.DeletedDate IS NULL;
	SELECT Children.*, TribeID  
	FROM Children LEFT OUTER JOIN TribalAffiliation On (Children.ChildID = TribalAffiliation.ClientID And TribalAffiliation.ClientTypeID = 2)
	WHERE (ParticipantID = @ParticipantID) AND (DeletedDate IS NULL)  
	ORDER BY DOB;  	 
	SELECT * FROM Aliases
	WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI;
	SELECT *  
	FROM EmerContacts  
	WHERE (ParticipantID = @ParticipantID) AND (DeletedDate IS NULL)
	ORDER BY ContactName; 

proc_GetParticipantFile
CREATE PROCEDURE dbo.proc_GetParticipantFile
	(@FileID INT)
	AS
	SELECT FileData FROM ParticipantFiles WHERE FileID = @FileID

proc_GetParticipantFileInfo
CREATE PROCEDURE dbo.proc_GetParticipantFileInfo
	(@ParticipantID INT)
	AS
	SELECT FileID, ShortFileName, FileSize, Extension, CreatedDate, CreatedBy
	FROM ParticipantFiles
	WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL
	ORDER BY ShortFileName

proc_GetParticipantLists
CREATE PROCEDURE dbo.proc_GetParticipantLists
	(@ParticipantID INT)
	AS
	SELECT IntakeID, EntryDate, ExitDate, s.ShelterName, x.IntakeType
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
	WHERE ParticipantID = @ParticipantID And i.DeletedDate IS NULL
	ORDER BY EntryDate;	
	
	SELECT  NoteType = 1, NoteID, NoteDate, Subject, NoteText, StartTime = '', EndTime = '', CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Notes
	WHERE ClientID = @ParticipantID And ClientTypeID = 1 And DeletedDate Is Null
	UNION ALL
	SELECT NoteType = 2, s.SessionID, SessionDate, ServiceName, Note, sn.StartTime, sn.EndTime, s.CreatedDate, s.CreatedBy, s.ModifiedDate, s.ModifiedBy
	FROM Services ss INNER JOIN [Sessions] s ON ss.ServiceID = s.ServiceID
		INNER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
	WHERE cs.ClientID = @ParticipantID AND cs.ClientTypeID = 1 AND s.DeletedDate IS NULL	
	ORDER BY NoteType, NoteDate;
	
	SELECT cs.SessionID, SessionDate, ServiceName AS Service, Program, SessionHours, 
		s.NumberStaff, ISNULL(sf.LastName + ', ' + sf.FirstName, '') AS StaffName 
	FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID AND s.DeletedDate IS NULL
		INNER JOIN Programs p ON s.ProgramID = p.ProgramID
		INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
		LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
		LEFT OUTER JOIN Staff sf ON sts.StaffID = sf.StaffID AND sf.DeletedDate IS NULL
	WHERE cs.ClientID = @ParticipantID AND cs.ClientTypeID = 1 AND cs.DeletedDate IS NULL
	ORDER BY SessionDate DESC

	SELECT r.ReferralID, ReferralType, ReferralDate, NumberReferrals, Agency, ISNULL(LastName + ', ' + FirstName, '') AS StaffName
	FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
		LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
		LEFT OUTER JOIN Staff s ON s.StaffID = sr.StaffID
	WHERE ClientID = @ParticipantID AND ClientTypeID = 1 And r.DeletedDate Is Null
	ORDER BY r.ReferralDate DESC;

	SELECT FileID, ShortFileName, FileSize, Extension, CreatedDate, CreatedBy
	FROM ParticipantFiles
	WHERE ParticipantID = @ParticipantID AND DeletedDate IS NULL
	ORDER BY ShortFileName; 

proc_GetPhases
CREATE PROCEDURE dbo.proc_GetPhases
	AS
	SELECT PhaseID, Phase = CASE
		WHEN IsCurrent = 0 THEN '*' + PhaseName ELSE PhaseName END, PhaseName, Sequence, IntakeType,
		p.IntakeTypeID, ProjectedLength, IsCurrent, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM Phases p INNER JOIN xIntakeType x ON p.IntakeTypeID = x.IntakeTypeID 
	WHERE DeletedDate IS NULL
	ORDER BY IntakeTypeID, Sequence, PhaseName

proc_GetPresentation
-- Combine queries into single procedure for retrieving Presentation data
CREATE PROCEDURE dbo.proc_GetPresentation
	(@PresentationID INT)
	AS
	SELECT TOP 1 * FROM Presentations WHERE PresentationID = @PresentationID;
	SELECT StaffID FROM StaffPresentations WHERE PresentationID = @PresentationID;
	SELECT TopicID FROM PresentationTopics WHERE PresentationID = @PresentationID;

proc_GetPresentationLists
CREATE PROCEDURE dbo.proc_GetPresentationLists
	AS
	DECLARE @True BIT, @False BIT
	SET @True = 1 SET @False = 0
	SELECT StaffID, Status, StaffName = CASE
		WHEN DateLeft IS NULL THEN LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		ELSE '*' + LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		END,
		IsCurrent = CASE WHEN DateLeft IS NULL THEN @True ELSE @False END
	FROM Staff WHERE DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI;
	SELECT TopicID, Topic = CASE
		WHEN IsCurrent = 1 THEN Topic ELSE '*' + Topic END, IsCurrent
	FROM xTopic
	WHERE DeletedDate IS NULL
	ORDER BY Topic;

proc_GetPresentations
CREATE PROCEDURE dbo.proc_GetPresentations
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByPresentationDate BIT)
	AS
	IF @ByPresentationDate = 1
		SELECT PresentationID, PresentationDate, Location, PresentationHours, NumberAttended, YouthTargeted, IsPresentation
		FROM Presentations
		WHERE PresentationDate Between @FromDate And @ToDate And DeletedDate Is Null
		ORDER BY PresentationDate
	ELSE
		SELECT PresentationID, PresentationDate, Location, PresentationHours, NumberAttended, YouthTargeted, IsPresentation
		FROM Presentations
		WHERE ModifiedDate Between @FromDate And @ToDate And DeletedDate Is Null
		ORDER BY ModifiedDate	

proc_GetPrompts
CREATE PROCEDURE dbo.proc_GetPrompts
	AS
	SELECT TOP 1 MaxDaysToComplete, MaxDaysInactive, MaxDaysSinceCall
	FROM zsSettings

proc_GetQuestionnaire
CREATE PROCEDURE dbo.proc_GetQuestionnaire
	(@QuestionnaireID INT)
	AS
	-- Questionnaire
	SELECT TOP 1 SurveyID, q.IntakeID, CompletedDate, ControlNumber, q.ClientTypeID,
	q.CreatedBy, q.CreatedDate, q.ModifiedBy, q.ModifiedDate,
	ClientID = CASE
		WHEN ClientTypeID = 1 THEN ISNULL(i.ParticipantID, 0)
		WHEN ClientTypeID = 2 THEN ISNULL(ci.ChildID, 0)
		WHEN ClientTypeID = 3 THEN ISNULL(ai.AbuserID, 0)
		END 
	FROM Questionnaires q LEFT OUTER JOIN Intakes i ON q.IntakeID = i.IntakeID AND q.ClientTypeID = 1
		LEFT OUTER JOIN ChildIntakes ci ON q.IntakeID = ci.ChildIntakeID AND q.ClientTypeID = 2
		LEFT OUTER JOIN AbuserIntakes ai ON q.IntakeID = ai.AbuserIntakeID AND q.ClientTypeID = 3
	WHERE QuestionnaireID = @QuestionnaireID;
	-- Numeric responses
	SELECT QuestionID, Response
	FROM QuestionResponses
	WHERE QuestionnaireID = @QuestionnaireID;
	-- Narrative responses
	SELECT NarrativeID, Narrative
	FROM NarrativeResponses
	WHERE QuestionnaireID = @QuestionnaireID;

proc_GetQuestionnaires
CREATE PROCEDURE dbo.proc_GetQuestionnaires
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByEditDate BIT)
	AS
	IF @ByEditDate = 0
	BEGIN
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND p.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON i.IntakeID = q.IntakeID AND q.ClientTypeID = 1
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE CompletedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID, 
			c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
		FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID AND c.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON ci.ChildIntakeID = q.IntakeID AND q.ClientTypeID = 2
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE CompletedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			a.LastName + ', ' + a.FirstName + ' ' + a.MI AS ClientName
		FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID AND a.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON ai.AbuserIntakeID = q.IntakeID AND q.ClientTypeID = 3
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE CompletedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			ClientName = CASE
				WHEN q.ClientTypeID = 1 THEN ''
				WHEN q.ClientTypeID = 2 THEN ''
				WHEN q.ClientTypeID = 3 THEN '' END
		FROM Questionnaires q INNER JOIN Surveys s ON q.SurveyID = s.SurveyID AND s.IsAnonymous = 1
		WHERE CompletedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL AND s.DeletedDate IS NULL
	END
	ELSE
	BEGIN
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND p.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON i.IntakeID = q.IntakeID AND q.ClientTypeID = 1
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE q.ModifiedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL
		
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID, 
			c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
		FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID AND c.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON ci.ChildIntakeID = q.IntakeID AND q.ClientTypeID = 2
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE q.ModifiedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL	
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			a.LastName + ', ' + a.FirstName + ' ' + a.MI AS ClientName
		FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID AND a.DeletedDate IS NULL
			INNER JOIN Questionnaires q ON ai.AbuserIntakeID = q.IntakeID AND q.ClientTypeID = 3
			INNER JOIN Surveys s ON q.SurveyID = s.SurveyID
		WHERE q.ModifiedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL 
			AND s.DeletedDate IS NULL AND s.IsAnonymous = 0
		UNION ALL		
		SELECT q.QuestionnaireID, s.SurveyName, q.CompletedDate, q.ControlNumber, q.IntakeID,
			ClientName = CASE
				WHEN q.ClientTypeID = 1 THEN ''
				WHEN q.ClientTypeID = 2 THEN ''
				WHEN q.ClientTypeID = 3 THEN '' END
		FROM Questionnaires q INNER JOIN Surveys s ON q.SurveyID = s.SurveyID AND s.IsAnonymous = 1
		WHERE q.ModifiedDate BETWEEN @FromDate AND @ToDate AND q.DeletedDate IS NULL AND s.DeletedDate IS NULL
	END

proc_GetReferral
CREATE PROCEDURE dbo.proc_GetReferral
	(@ReferralID INT)
	AS
	SELECT TOP 1 * 
	FROM Referrals 
	WHERE ReferralID = @ReferralID
	RETURN

proc_GetReferrals
CREATE PROCEDURE dbo.proc_GetReferrals
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByReferralDate BIT)
	AS
		IF @ByReferralDate = 1
			BEGIN
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (P)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Participants p INNER JOIN Referrals r On p.ParticipantID = r.ClientID 
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 1 And ReferralDate Between @FromDate And @ToDate And r.DeletedDate Is Null And p.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (C)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Children c INNER JOIN Referrals r On c.ChildID = r.ClientID 
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 2 And ReferralDate Between @FromDate And @ToDate And r.DeletedDate Is Null  And c.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (A)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Abusers a INNER JOIN Referrals r On a.AbuserID = r.ClientID 
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 3 And ReferralDate Between @FromDate And @ToDate And r.DeletedDate Is Null And a.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (M)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM CommunityMembers cm INNER JOIN Referrals r ON cm.MemberID = r.ClientID
					INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 4 AND ReferralDate BETWEEN @FromDate AND @ToDate AND r.DeletedDate IS NULL AND cm.DeletedDate IS NULL
				ORDER BY ReferralDate
			END
		ELSE
			BEGIN
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (P)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Participants p INNER JOIN Referrals r On p.ParticipantID = r.ClientID
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 1 And r.ModifiedDate Between @FromDate And @ToDate And r.DeletedDate Is Null And p.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (C)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Children c INNER JOIN Referrals r On c.ChildID = r.ClientID 
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 2 And r.ModifiedDate Between @FromDate And @ToDate And r.DeletedDate Is Null And c.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (A)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM Abusers a INNER JOIN Referrals r On a.AbuserID = r.ClientID 
					INNER JOIN xReferralType x On r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 3 And r.ModifiedDate Between @FromDate And @ToDate And r.DeletedDate Is Null And a.DeletedDate IS NULL
				UNION ALL
				SELECT ReferralID, ReferralType, LastName + ', ' + FirstName + ' ' + MI + ' (M)' AS FullName, Agency, NumberReferrals, ReferralDate, r.ModifiedDate
				FROM CommunityMembers cm INNER JOIN Referrals r ON cm.MemberID = r.ClientID
					INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
				WHERE r.ClientTypeID = 4 AND r.ModifiedDate BETWEEN @FromDate AND @ToDate AND r.DeletedDate IS NULL AND cm.DeletedDate IS NULL 
				ORDER BY r.ModifiedDate
			END

proc_GetReportLists
CREATE PROCEDURE dbo.proc_GetReportLists
	AS
	SELECT ItemValue AS Organization
	FROM zShelterData
	WHERE Item = 'Organization';
	SELECT DISTINCT SurveyName, s.SurveyID, IsAnonymous, IsCurrent, CASE
		WHEN IsCurrent = 1 THEN SurveyName
		ELSE '*' + SurveyName END AS Survey, 
		HasQuestions = CAST(CASE WHEN sq.SurveyID IS NULL THEN 0 ELSE 1 END AS BIT),
		HasNarratives = CAST(CASE WHEN sn.SurveyID IS NULL THEN 0 ELSE 1 END AS BIT),
		MaxRating = ISNULL((SELECT MAX(MaxRating) AS MaxRating
			FROM Surveys ss INNER JOIN SurveyQuestions sq ON s.SurveyID = sq.SurveyID
				INNER JOIN Questions q ON sq.QuestionID = q.QuestionID
			WHERE ss.SurveyID = s.SurveyID), 0)
	FROM Surveys s LEFT OUTER JOIN SurveyQuestions sq on s.SurveyID = sq.SurveyID
		LEFT OUTER JOIN SurveyNarratives sn ON s.SurveyID = sn.SurveyID
	WHERE DeletedDate IS NULL
	ORDER BY SurveyName;
	SELECT GrantID,
		IsCurrent = CASE WHEN GrantEnd < GETDATE() THEN 0 ELSE 1 END,
		Grantor = CASE WHEN GrantEnd < GETDATE() THEN '*' ELSE '' END +
			gg.Grantor + ' (' + Convert(VarChar(50), GrantStart, 110) + ' - ' + Convert(VarChar(50), GrantEnd, 110) + ')',
		GrantStart, GrantEnd, g.ContractNumber
	FROM Grants g INNER JOIN Grantors gg ON g.GrantorID = gg.GrantorID
	WHERE g.DeletedDate IS NULL
	ORDER BY gg.Grantor;
	SELECT StaffID, LastName + ', ' + FirstName + CASE
		WHEN LEN(MI) = 0 THEN '' ELSE ' ' + MI + '.' END AS FullName
	FROM Staff
	WHERE DateLeft IS NULL AND DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI;

proc_GetReportNarrative
CREATE PROCEDURE dbo.proc_GetReportNarrative
	(@NarrativeID INT)
	AS
	SELECT Top 1 *
	FROM ReportNarratives
	WHERE NarrativeID = @NarrativeID
	RETURN

proc_GetReportNarratives
CREATE PROCEDURE dbo.proc_GetReportNarratives
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ByReportDate BIT)
	AS
	IF @ByReportDate = 1
		SELECT ReportDate, ReportNumber, Item, NarrativeID 
		FROM ReportNarratives
		WHERE (ReportDate Between @StartDate And @EndDate) AND DeletedDate IS NULL
		ORDER BY ReportDate Desc, Item
	ELSE
		SELECT *
		FROM ReportNarratives
		WHERE (ModifiedDate Between @StartDate And @EndDate) AND DeletedDate IS NULL
		ORDER BY ModifiedDate Desc

proc_GetRevisionNumber
CREATE PROCEDURE dbo.proc_GetRevisionNumber
	AS
	SELECT Revision FROM zsSettings
	RETURN

proc_GetRoom
CREATE PROCEDURE dbo.proc_GetRoom
	(@RoomID INT)
	AS
	SELECT TOP 1 Rooms.*, ShelterName
	FROM Rooms Inner Join Shelters On Rooms.ShelterID = Shelters.ShelterID
	WHERE RoomID = @RoomID
	RETURN

proc_GetRoomBedAssignment
CREATE PROCEDURE dbo.proc_GetRoomBedAssignment
	(@RoomBedAssignmentID INT)
	AS
	SELECT TOP 1 *
	FROM RoomBedAssignments
	WHERE RoomBedAssignmentID = @RoomBedAssignmentID
	RETURN

proc_GetServiceSession
CREATE PROCEDURE dbo.proc_GetServiceSession
	(@SessionID INT)
	AS
	-- Session data
	SELECT ProgramID, ServiceID, FocusID, SessionDate, SessionHours, NumberStaff, LocationID, ByPhone, 
		PurposeID, Destination, OneWay, MilesOneWay, DestinationCountyID, VehicleID, StartTime, EndTime, Note,
		CreatedDate, CreatedBy, ModifiedDate, ModifiedBy
	FROM [Sessions] s LEFT OUTER JOIN Trips t ON s.SessionID = t.TripID
		LEFT OUTER JOIN SessionNotes sn ON s.SessionID = sn.SessionID
	WHERE s.SessionID = @SessionID And DeletedDate Is Null;
	-- Staff in session
	SELECT StaffID
	FROM StaffSessions
	WHERE SessionID = @SessionID;
	-- Clients in session
	SELECT ClientID, ClientTypeID, IntakeID, 'Participant' AS Type,
		LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ') ' AS FullName
	FROM ClientSessions cs INNER JOIN Participants p ON cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
	WHERE SessionID = @SessionID AND cs.DeletedDate IS NULL
	UNION ALL
	SELECT ClientID, ClientTypeID, IntakeID, 'Child' AS Type,
		LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ') ' AS FullName
	FROM ClientSessions cs INNER JOIN Children c ON cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
	WHERE SessionID = @SessionID AND cs.DeletedDate IS NULL
	UNION ALL
	SELECT ClientID, ClientTypeID, IntakeID, 'Abuser' AS Type,
		LastName + ', ' + FirstName + ' ' + MI + ' (' + CONVERT(VARCHAR(50), DOB, 110) + ') ' AS FullName
	FROM ClientSessions cs INNER JOIN Abusers a ON cs.ClientID = a.AbuserID AND cs.ClientTypeID = 3
	WHERE SessionID = @SessionID AND cs.DeletedDate IS NULL
	UNION ALL
	SELECT ClientID, ClientTypeID, IntakeID = 0, 'Community' AS Type,
		LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM ClientSessions cs INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
	WHERE SessionID = @SessionID AND cs.DeletedDate IS NULL
	ORDER BY FullName;
	-- Tangible goods
	SELECT tg.GoodTypeID, tg.Quantity, x.GoodType
	FROM TangibleGoods tg INNER JOIN xGoodType x ON tg.GoodTypeID = x.GoodTypeID
	WHERE tg.SessionID = @SessionID;

proc_GetServiceSessions
CREATE PROCEDURE dbo.proc_GetServiceSessions
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByEditDate BIT)
	AS
	IF @ByEditDate = 1
		BEGIN
			SELECT s.SessionID, SessionDate, ss.ServiceName, ISNULL(f.Focus, '') AS Focus, p.Program, SessionHours, 
				NumberStaff, ISNULL(LastName + ', ' + FirstName, '') AS StaffName 
			FROM [Sessions] s INNER JOIN Programs p ON s.ProgramID = p.ProgramID
				INNER JOIN Services ss on s.ServiceID = ss.ServiceID
				LEFT OUTER JOIN Focus f ON s.FocusID = f.FocusID
				LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
				LEFT OUTER JOIN Staff st ON st.StaffID = sts.StaffID AND st.DeletedDate IS NULL
			WHERE s.ModifiedDate Between @FromDate And @ToDate And s.DeletedDate Is Null
			ORDER BY SessionDate, s.SessionID
		END
	ELSE
		BEGIN
			SELECT s.SessionID, SessionDate, ss.ServiceName, ISNULL(f.Focus, '') AS Focus, p.Program, SessionHours, 
				NumberStaff, ISNULL(LastName + ', ' + FirstName, '') AS StaffName 
			FROM [Sessions] s INNER JOIN Programs p ON s.ProgramID = p.ProgramID
				INNER JOIN Services ss on s.ServiceID = ss.ServiceID
				LEFT OUTER JOIN Focus f ON s.FocusID = f.FocusID
				LEFT OUTER JOIN StaffSessions sts ON s.SessionID = sts.SessionID
				LEFT OUTER JOIN Staff st ON st.StaffID = sts.StaffID AND st.DeletedDate IS NULL
			WHERE SessionDate Between @FromDate And @ToDate And s.DeletedDate Is Null
			ORDER BY SessionDate, s.SessionID
		END

proc_GetServicesLists
-- Add another recordset of ShelterServices; also, don't retrieve the Focus of  (FocusID = 0) for the Focus list
CREATE PROCEDURE dbo.proc_GetServicesLists
	AS
	SELECT ServiceID, ServiceName, IsGroup, IsFamily, ByPhone, InPerson, DiscontinuedDate, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate 
	FROM Services WHERE DeletedDate Is Null ORDER BY ServiceName;
	SELECT GrantorID, Grantor, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate
	FROM Grantors WHERE DeletedDate Is Null ORDER BY Grantor;
	SELECT ProgramID, Program AS ProgramName, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate,
		Program = CASE WHEN IsCurrent = 0 THEN '*' + Program ELSE Program END
	FROM Programs WHERE DeletedDate Is Null	ORDER BY ProgramName;
	SELECT FocusID, Focus AS FocusName, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate,
		Focus = CASE WHEN IsCurrent = 0 THEN '*' + Focus ELSE Focus END
	FROM Focus WHERE DeletedDate Is Null AND FocusID > 0 ORDER BY FocusName;
	SELECT GrantorServiceID, GrantorService, GrantorID
	FROM GrantorServices WHERE DeletedDate Is Null ORDER BY GrantorService;
	SELECT Mapping = CASE WHEN sf.FocusID = 0 THEN ServiceName + ' = ' + GrantorService
			ELSE ServiceName + ':' + f.Focus  + ' = ' + GrantorService END,
		sf.ServiceID, f.FocusID, sf.ServiceFocusID, gs.GrantorID, f.Focus, s.ServiceName
	FROM GrantorServices gs INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
		INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Services s ON sf.ServiceID = s.ServiceID
		INNER JOIN Focus f ON sf.FocusID = f.FocusID
	WHERE s.DiscontinuedDate Is Null AND s.DeletedDate Is Null ORDER BY ServiceName;
	SELECT ProgramID, ps.ServiceID, ServiceName FROM ProgramServices ps 
		INNER JOIN [Services] s ON ps.ServiceID = s.ServiceID ORDER BY ProgramID, ServiceName;
	SELECT FocusID, sf.ServiceID, ServiceName FROM ServiceFocus sf 
		INNER JOIN [Services] s ON sf.ServiceID = s.ServiceID
		ORDER BY FocusID, ServiceName;
	SELECT s.ServiceName, f.Focus, s.ServiceID, f.FocusID, sf.ServiceFocusID
	FROM Services s INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID
		INNER JOIN Focus f ON sf.FocusID = f.FocusID
	WHERE f.IsCurrent = 1 AND f.DeletedDate IS NULL AND s.DiscontinuedDate IS NULL
	ORDER BY ServiceName, f.Focus;

proc_GetServicesProgramsFocuses
-- Change the procedure for retrieving programs, services, and focus to no longer add a FocusID = 0 ''
CREATE PROCEDURE proc_GetServicesProgramsFocuses
	AS
	SELECT ServiceID, 
		Service = CASE WHEN DiscontinuedDate IS NULL THEN ServiceName ELSE '*' + ServiceName END,
		IsCurrent = CASE WHEN DiscontinuedDate IS NULL THEN 1 ELSE 0 END, IsGroup, ByPhone
	FROM [Services]
	WHERE DeletedDate IS NULL
	ORDER BY ServiceName
	SELECT p.ProgramID, Program = CASE WHEN IsCurrent = 1 THEN Program ELSE '*' + Program END, IsCurrent, ServiceID
	FROM Programs p INNER JOIN ProgramServices ps ON p.ProgramID = ps.ProgramID
	WHERE DeletedDate IS NULL
	ORDER BY p.Program
	SELECT f.FocusID, Focus = CASE WHEN IsCurrent = 1 THEN Focus ELSE '*' + Focus END, IsCurrent, sf.ServiceID, FocusName = Focus
	FROM Focus f INNER JOIN ServiceFocus sf ON f.FocusID = sf.FocusID
	WHERE f.DeletedDate IS NULL
	ORDER BY FocusName

proc_GetServicesProgramsFocusesGoods
CREATE PROCEDURE proc_GetServicesProgramsFocusesGoods
	AS
	SELECT ServiceID, 
		Service = CASE WHEN DiscontinuedDate IS NULL THEN ServiceName ELSE '*' + ServiceName END,
		IsCurrent = CASE WHEN DiscontinuedDate IS NULL THEN 1 ELSE 0 END, IsGroup, ByPhone
	FROM [Services]
	WHERE DeletedDate IS NULL
	ORDER BY ServiceName;
	SELECT p.ProgramID, Program = CASE WHEN IsCurrent = 1 THEN Program ELSE '*' + Program END, IsCurrent, ServiceID
	FROM Programs p INNER JOIN ProgramServices ps ON p.ProgramID = ps.ProgramID
	WHERE DeletedDate IS NULL
	ORDER BY p.Program;
	SELECT f.FocusID, Focus = CASE WHEN IsCurrent = 1 THEN Focus ELSE '*' + Focus END, IsCurrent, sf.ServiceID, FocusName = Focus
	FROM Focus f INNER JOIN ServiceFocus sf ON f.FocusID = sf.FocusID
	WHERE f.DeletedDate IS NULL
	ORDER BY FocusName;
	SELECT GoodTypeID, GoodType,
		Display = CASE WHEN IsCurrent = 1 THEN GoodType ELSE '*' + GoodType END, IsCurrent
	FROM xGoodType
	WHERE DeletedDate IS NULL
	ORDER BY GoodType;

proc_GetShelter
CREATE PROCEDURE dbo.proc_GetShelter
	(@ShelterID INT)
	AS
	SELECT TOP 1 * 
	FROM Shelters 
	WHERE ShelterID = @ShelterID
	RETURN

proc_GetShelterBeds
CREATE PROCEDURE dbo.proc_GetShelterBeds
	(@AsOfDate SMALLDATETIME, @ShelterID INT)
	AS
	SELECT Beds.*, RoomID
	FROM Beds Inner Join RoomBedAssignments On Beds.BedID = RoomBedAssignments.BedID
	WHERE 
		Beds.ShelterID = @ShelterID
		AND
		Beds.ServiceStart <= @AsOfDate
		AND
		IsNull(Beds.ServiceEnd, '6/6/2079') > @AsOfDate
		AND
		(@AsOfDate >= RoomBedAssignments.DateAssigned AND @AsOfDate < IsNull(RoomBedAssignments.DateMoved, '6/6/2079'))
		AND
		Beds.DeletedDate Is Null
	SELECT DISTINCT Beds.*, RoomID = -1
	FROM Beds
	WHERE 
		ShelterID = @ShelterID AND Beds.ServiceStart <= @AsOfDate
		AND
		ISNULL(Beds.ServiceEnd, '6/6/2079') > @AsOfDate
		AND
		BedID NOT IN (
			SELECT Beds.BedID
			FROM Beds Inner Join RoomBedAssignments On Beds.BedID = RoomBedAssignments.BedID
			WHERE 
				Beds.ShelterID = @ShelterID
				AND
				Beds.ServiceStart <= @AsOfDate
				AND
				IsNull(Beds.ServiceEnd, '6/6/2079') > @AsOfDate
				AND
				(@AsOfDate >= RoomBedAssignments.DateAssigned AND @AsOfDate < IsNull(RoomBedAssignments.DateMoved, '6/6/2079'))
				AND
				Beds.DeletedDate Is Null
				)
	ORDER BY Beds.Description

proc_GetShelterCollections
CREATE PROCEDURE dbo.proc_GetShelterCollections
	AS
	SELECT * FROM Campuses WHERE DeletedDate Is Null ORDER BY CampusName;
	SELECT s.*, CONVERT(BIT, 1) AS RelatedRecords
	FROM Shelters s
	WHERE s.DeletedDate IS NULL AND
		(
		((SELECT TOP 1 ShelterID FROM Intakes WHERE ShelterID = s.ShelterID) IS NOT NULL)
		OR
		((SELECT TOP 1 ShelterID FROM Rooms WHERE ShelterID = s.ShelterID) IS NOT NULL)
		OR
		((SELECT TOP 1 ShelterID FROM Beds WHERE ShelterID = s.ShelterID) IS NOT NULL)
		)
	UNION ALL
	SELECT s.*, CONVERT(BIT, 0) AS RelatedRecords
	FROM Shelters s
	WHERE s.DeletedDate IS NULL AND
		(
		((SELECT TOP 1 ShelterID FROM Intakes WHERE ShelterID = s.ShelterID) IS  NULL)
		AND
		((SELECT TOP 1 ShelterID FROM Rooms WHERE ShelterID = s.ShelterID) IS  NULL)
		AND
		((SELECT TOP 1 ShelterID FROM Beds WHERE ShelterID = s.ShelterID) IS  NULL)
		)
	ORDER BY ShelterName;
	SELECT Rooms.*, ShelterName 
	FROM Rooms INNER JOIN Shelters on Rooms.ShelterID = Shelters.ShelterID
	WHERE Rooms.DeletedDate Is Null And Shelters.DeletedDate Is Null
	ORDER BY ShelterName, RoomNumber;
	SELECT Beds.*, ShelterName 
	FROM Beds INNER JOIN Shelters ON Beds.ShelterID = Shelters.ShelterID
	WHERE Beds.DeletedDate Is Null And Shelters.DeletedDate Is Null
	ORDER BY ShelterName, Description;
	SELECT RoomNumber, ShelterID, RoomBedAssignments.*
	FROM RoomBedAssignments Inner Join Rooms On RoomBedAssignments.RoomID = Rooms.RoomID
	WHERE Rooms.DeletedDate Is Null
	ORDER BY ShelterID, BedID, DateAssigned;

proc_GetShelters
CREATE PROCEDURE dbo.proc_GetShelters
	AS
	SELECT ShelterID, ShelterName, Residential, NonResidential, ShelterTypeID
	FROM Shelters
	WHERE DeletedDate IS NULL AND IsCurrent = 1

proc_GetStaffMember
CREATE PROCEDURE dbo.proc_GetStaffMember
	(@StaffID INT)
	AS
	SELECT TOP 1 * FROM Staff WHERE StaffID = @StaffID

proc_GetStaffMemberExt
CREATE PROCEDURE dbo.proc_GetStaffMemberExt
	(@StaffID INT)
	AS
	SELECT s.StaffID, FirstName, MI, LastName, Title, ServiceProvider, Status, DateLeft, 
		s.CreatedBy, s.CreatedDate, s.ModifiedBy, s.ModifiedDate,
		se.Address, se.City, se.CreatedBy AS CreatedBySe, se.CreatedDate AS CreatedDateSe,
		se.DOB, se.Email, se.Ext, se.HireDate, se.HomePhone, se.LastEvalDate, se.MobilePhone,
		se.Rehire, se.RehireComment, 
		se.ModifiedBy as ModifiedBySe, se.ModifiedDate AS ModifiedDateSe,
		se.State, se.WorkPhone, se.Zip, se.StaffID AS StaffIDse, 
		sr.StaffID AS StaffIDsr, sr.RequirementID, sr.DueDate, sr.CompletedDate,
		ISNULL(c.Credential, '') AS RequirementName, ISNULL(c.Frequency, -2) AS Frequency 
	FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
		LEFT OUTER JOIN StaffRequirements sr ON s.StaffID = sr.StaffID
		LEFT OUTER JOIN Credentials c ON sr.RequirementID = c.CredentialID AND c.Frequency > -2 AND c.IsCurrent = 1
	WHERE s.StaffID = @StaffID

proc_GetStaffMembers
CREATE PROCEDURE dbo.proc_GetStaffMembers
	AS
		DECLARE @True BIT, @False BIT SET @True = 1 SET @False = 0
		SELECT StaffID, Title, ServiceProvider, [Status], StaffName = CASE
		WHEN DateLeft IS NULL THEN LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		ELSE '*' + LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		END,
		IsCurrent = CASE WHEN DateLeft IS NULL THEN @True ELSE @False END
		FROM Staff
		WHERE DeletedDate Is Null
		ORDER BY LastName, FirstName, MI

proc_GetStaffMembersExt
CREATE PROCEDURE dbo.proc_GetStaffMembersExt
	AS
		DECLARE @True BIT, @False BIT SET @True = 1 SET @False = 0
		SELECT StaffID, Title, ServiceProvider, [Status], StaffName = CASE
			WHEN DateLeft IS NULL THEN LastName + ', ' + FirstName + CASE
				WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
				ELSE ''
				END
			ELSE '*' + LastName + ', ' + FirstName + CASE
				WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
				ELSE ''
				END
			END,
			IsCurrent = CASE WHEN DateLeft IS NULL THEN @True ELSE @False END
		FROM Staff
		WHERE DeletedDate Is Null
		ORDER BY LastName, FirstName, MI;
		SELECT CredentialID AS RequirementID, [Credential] AS Requirement, Frequency, IsCurrent 
		FROM [Credentials]
		WHERE Frequency > -2 AND IsCurrent = 1 AND DeletedDate IS NULL
		ORDER BY Requirement

proc_GetStaffReferrals
CREATE PROCEDURE dbo.proc_GetStaffReferrals
	(@ReferralID INT)
	AS
	SELECT StaffID
	FROM StaffReferrals
	WHERE ReferralID = @ReferralID

proc_GetStaffRequirements
CREATE PROCEDURE dbo.proc_GetStaffRequirements
	(@StaffID INT)
	AS
	SELECT RequirementID, DueDate, CompletedDate, Credential AS RequirementName, Frequency
	FROM StaffRequirements sr INNER JOIN Credentials c ON sr.RequirementID = c.CredentialID
	WHERE StaffID = @StaffID AND c.DeletedDate IS NULL
	ORDER BY RequirementName

proc_GetStaffTrainingRequirements
CREATE PROCEDURE dbo.proc_GetStaffTrainingRequirements
	(@SessionDate SMALLDATETIME, @SubjectID INT)
	AS
	SELECT Staff.StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName
	FROM Staff
	WHERE Staff.DeletedDate IS NULL And Staff.DateLeft IS NULL And Staff.StaffID IN
	(
		SELECT StaffRequirements.StaffID
		FROM StaffRequirements INNER JOIN Credentials ON StaffRequirements.RequirementID = Credentials.CredentialID
		WHERE
			RequirementID = @SubjectID
			AND
			(StaffRequirements.CompletedDate IS NULL Or StaffRequirements.CompletedDate < @SessionDate)	
			AND
			Credentials.Frequency > -2
			AND
			Credentials.DeletedDate IS NULL
	)
	ORDER BY FullName

proc_GetSurvey
CREATE PROCEDURE dbo.proc_GetSurvey
	(@SurveyID INT)
	AS
	SELECT TOP 1 SurveyName, IsAnonymous, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate, 
		HasResponses = CASE
		WHEN (SELECT TOP 1 SurveyID FROM Questionnaires WHERE SurveyID = @SurveyID AND DeletedDate IS NULL) IS NULL THEN 0
		ELSE 1 END	
	FROM Surveys s
	WHERE SurveyID = @SurveyID;
	SELECT sq.QuestionID, QuestionNumber, Question, MaxRating
	FROM SurveyQuestions sq INNER JOIN Questions q ON sq.QuestionID = q.QuestionID
	WHERE sq.SurveyID = @SurveyID
	ORDER BY QuestionNumber, sq.QuestionID;
	SELECT NarrativeID, [Description]
	FROM SurveyNarratives
	WHERE SurveyID = @SurveyID;
	SELECT gs.GrantID
	FROM GrantSurveys gs INNER JOIN Grants g ON gs.GrantID = g.GrantID
	WHERE gs.SurveyID = @SurveyID AND g.DeletedDate IS NULL;

proc_GetSurveyLists
CREATE PROCEDURE proc_GetSurveyLists
	AS
	-- Surveys
	SELECT SurveyID, SurveyName, IsCurrent, IsAnonymous, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate,
		NumberQuestionnaires =
		(SELECT COUNT(QuestionnaireID) FROM Questionnaires WHERE SurveyID = s.SurveyID) 
	FROM Surveys s
	WHERE DeletedDate IS NULL
	ORDER BY SurveyName;
	-- Grants	 
	SELECT GrantID, Grantor, GrantStart, GrantEnd, IsCurrent = CASE
		WHEN getdate() >= GrantStart And getdate() <= GrantEnd THEN 1
		ELSE 0 END
	FROM Grants g Inner Join Grantors gg On g.GrantorID = gg.GrantorID
	WHERE g.DeletedDate Is Null And gg.DeletedDate Is Null
	ORDER BY GrantStart
	-- Questions & Outcomes
	SELECT Goal, Questions.GoalID, Question, Outcome, QuestionID, MaxRating, Questions.IsCurrent, Questions.CreatedBy,
		Questions.IsSafety, Questions.IsResource, Questions.IsShelter, Questions.IsServices, Questions.IsCounseling,
		Questions.IsGroup, Questions.CreatedDate, Questions.ModifiedBy, Questions.ModifiedDate 
	FROM Questions INNER JOIN Goals ON Questions.GoalID = Goals.GoalID
	WHERE Questions.DeletedDate Is Null 
	ORDER BY Goals.GoalID, QuestionID;
	-- Goals
	SELECT GoalID, Goal
	FROM Goals
	ORDER BY GoalID;
	-- SurveyQuestions
	SELECT SurveyID, QuestionID, QuestionNumber
	FROM SurveyQuestions
	ORDER BY SurveyID, QuestionNumber;
	-- SurveyNarratives
	SELECT NarrativeID, SurveyID, Description
	FROM SurveyNarratives
	ORDER BY SurveyID;
	-- GrantSurveys
	SELECT GrantID, SurveyID
	FROM GrantSurveys
	ORDER BY SurveyID;

proc_GetSurveyResults
CREATE PROCEDURE dbo.proc_GetSurveyResults
	(@IntakeID INT)
	AS
	SELECT SurveyName, qs.SurveyID, qs.CompletedDate, qs.ControlNumber, QuestionNumber, Response, q.QuestionID, Question, MaxRating
	FROM Surveys s
		INNER JOIN Questionnaires qs ON s.SurveyID = qs.SurveyID
		INNER JOIN QuestionResponses qr ON qs.QuestionnaireID = qr.QuestionnaireID
		INNER JOIN Questions q ON qr.QuestionID = q.QuestionID
		INNER JOIN SurveyQuestions sq ON q.QuestionID = sq.QuestionID AND sq.SurveyID = qs.SurveyID
	WHERE qs.IntakeID = @IntakeID
	ORDER BY SurveyName, QuestionNumber, QuestionID, CompletedDate

proc_GetSurveys
CREATE PROCEDURE dbo.proc_GetSurveys
	AS
	SELECT SurveyID, SurveyName, Frequency, IsCurrent, IsAnonymous, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate 
	FROM Surveys
	WHERE DeletedDate Is Null 
	ORDER BY SurveyName

proc_GetTANFvalues
CREATE PROCEDURE dbo.proc_GetTANFvalues
	AS
	SELECT * FROM TANF WHERE LockID = 1

proc_GetTaskAndPhaseStatus
CREATE PROCEDURE dbo.proc_GetTaskAndPhaseStatus
	AS
	-- Current Participants with Tasks
	SELECT DISTINCT i.IntakeTypeID, i.IntakeID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
		x.IntakeType, i.EntryDate
	FROM Intakes i INNER JOIN Participants p ON p.ParticipantID = i.ParticipantID
		INNER JOIN xIntakeType x ON x.IntakeTypeID = i.IntakeTypeID
		INNER JOIN Tasks t ON i.IntakeTypeID = t.IntakeTypeID
	WHERE i.ExitDate IS NULL AND t.IsCurrent = 1
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND t.DeletedDate IS NULL
	ORDER BY Participant;
	-- Current Participants in Phases
	SELECT DISTINCT i.IntakeTypeID, i.IntakeID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
		x.IntakeType, i.EntryDate
	FROM Intakes i INNER JOIN Phases ph ON i.IntakeTypeID = ph.IntakeTypeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
	WHERE i.ExitDate IS NULL AND ph.IsCurrent = 1
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND ph.DeletedDate IS NULL
	ORDER BY Participant;
	-- Task Status of current participants
	SELECT t.IntakeTypeID, i.IntakeID, t.Task, it.CompletedDate, i.EntryDate, t.TaskID
	FROM Intakes i INNER JOIN Tasks t ON i.IntakeTypeID = t.IntakeTypeID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
		INNER JOIN Participants p ON p.ParticipantID = i.ParticipantID
		LEFT OUTER JOIN IntakeTasks it ON it.IntakeID = i.IntakeID AND t.TaskID = it.TaskID
	WHERE i.ExitDate IS NULL AND t.IsCurrent = 1
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND t.DeletedDate IS NULL
	ORDER BY t.IntakeTypeID, t.DaysToComplete;	
	-- Phase status of current participants
	SELECT ph.IntakeTypeID, i.IntakeID, ph.PhaseName,  ph.PhaseID,
		ip.BeginDate, ip.ProjectedEnd, ip.CompletedDate, i.EntryDate, ph.ProjectedLength
	FROM Intakes i INNER JOIN Phases ph ON i.IntakeTypeID = ph.IntakeTypeID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
		INNER JOIN Participants p ON p.ParticipantID = i.ParticipantID
		LEFT OUTER JOIN IntakePhase ip ON i.IntakeID = ip.IntakeID AND ph.PhaseID = ip.PhaseID
	WHERE i.ExitDate IS NULL AND ph.IsCurrent = 1
		AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND ph.DeletedDate IS NULL
	ORDER BY ph.IntakeTypeID, ph.Sequence

proc_GetTasks
CREATE PROCEDURE dbo.proc_GetTasks
	AS
	SELECT TaskID, Task, TaskName = CASE WHEN IsCurrent = 0 THEN '*' + Task ELSE Task END, 
		x.IntakeType, t.IntakeTypeID, t.DaysToComplete, t.IsCurrent, 
		t.CreatedDate, t.CreatedBy, t.ModifiedBy, t.ModifiedDate
	FROM Tasks t INNER JOIN xIntakeType x ON t.IntakeTypeID = x.IntakeTypeID
	WHERE DeletedDate IS NULL
	ORDER BY t.IntakeTypeID, DaysToComplete

proc_GetTrainingLists
CREATE PROCEDURE dbo.proc_GetTrainingLists
	AS
	DECLARE @True BIT, @False BIT
	SET @True = 1 SET @False = 0
	SELECT StaffID, Status, StaffName = CASE
		WHEN DateLeft IS NULL THEN LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		ELSE '*' + LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		END,
		IsCurrent = CASE WHEN DateLeft IS NULL THEN 1 ELSE 0 END
	FROM Staff WHERE DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI;
	SELECT c.CredentialID AS SubjectID, Subject = CASE WHEN IsCurrent = 1 THEN Credential ELSE '*' + Credential END, IsCurrent,
		 Requirement = CASE WHEN Frequency > -2 THEN @True ELSE @False END
	FROM Credentials c
	WHERE IsSubject = 1 AND DeletedDate IS NULL
	ORDER BY [Credential];

proc_GetTrainingSession
CREATE PROCEDURE dbo.proc_GetTrainingSession
	(@SessionID INT)
	AS
	SELECT Top 1 *
	FROM TrainingSessions
	WHERE SessionID = @SessionID;
	SELECT StaffID FROM StaffTraining WHERE SessionID = @SessionID;

proc_GetTrainingSessions
CREATE PROCEDURE dbo.proc_GetTrainingSessions
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @BySessionDate BIT)
	AS
	IF @BySessionDate = 1
		SELECT SessionID, SessionDate, SessionHours, OnSite, Credential As Subject, SessionNote, 
		Facilitators, TrainingSessions.ModifiedBy, TrainingSessions.ModifiedDate
		FROM TrainingSessions INNER JOIN Credentials On TrainingSessions.SubjectID = Credentials.CredentialID
		WHERE SessionDate Between @FromDate and @ToDate And TrainingSessions.DeletedDate Is Null
		ORDER BY SessionDate
	ELSE
		SELECT SessionID, SessionDate, SessionHours, OnSite, Credential As Subject, SessionNote, 
		Facilitators, TrainingSessions.ModifiedBy, TrainingSessions.ModifiedDate
		FROM TrainingSessions INNER JOIN Credentials On TrainingSessions.SubjectID = Credentials.CredentialID
		WHERE TrainingSessions.ModifiedDate Between @FromDate and @ToDate And TrainingSessions.DeletedDate Is Null
		ORDER BY TrainingSessions.ModifiedDate

proc_GetUnlinkedIntakeCalls
CREATE PROCEDURE dbo.proc_GetUnlinkedIntakeCalls
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	SELECT c.CallID, LastName + ', ' + FirstName + ' ' + MI AS FullName, CallDate, sr.RequestOutcomeID, RequestOutcome, WalkIn, ShelterID
	FROM IntakeCalls ic RIGHT OUTER JOIN Calls c ON ic.CallID = c.CallID 
		INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
		INNER JOIN xRequestOutcome xr ON sr.RequestOutcomeID = xr.RequestOutcomeID
	WHERE ic.CallID IS NULL And sr.RequestOutcomeID BETWEEN 2 And 3 And CallDate Between @FromDate And @ToDate AND c.DeletedDate IS NULL
	ORDER BY CallDate

proc_GetUnlinkedIntakes
CREATE PROCEDURE dbo.proc_GetUnlinkedIntakes
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME)
	AS
	SELECT i.IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, EntryDate, i.IntakeTypeID, IntakeType
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
		LEFT OUTER JOIN IntakeCalls ON i.IntakeID = IntakeCalls.IntakeID
	WHERE IntakeCalls.IntakeID IS NULL And i.IntakeTypeID In (1,3) 
		And EntryDate BETWEEN @FromDate And @ToDate AND i.DeletedDate IS NULL
	ORDER BY EntryDate

proc_GetVolunteerActivities
CREATE PROCEDURE dbo.proc_GetVolunteerActivities
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ByActivityDate BIT)
	AS
		IF @ByActivityDate = 1
			SELECT vas.ActivityID, ActivityDate, Activity, COUNT(va.ActivityID) + OneTimeVolunteers AS Volunteers
			FROM VolunteerActivities vas LEFT OUTER JOIN VolunteerActivity va ON vas.ActivityID = va.ActivityID
			WHERE ActivityDate Between @FromDate And @ToDate And vas.DeletedDate Is Null
			GROUP BY vas.ActivityID, ActivityDate, Activity, OneTimeVolunteers
			ORDER BY ActivityDate
		ELSE
			SELECT vas.ActivityID, Activity, ActivityDate, COUNT(va.ActivityID) + OneTimeVolunteers AS Volunteers
			FROM VolunteerActivities vas LEFT OUTER JOIN VolunteerActivity va ON vas.ActivityID = va.ActivityID
			WHERE vas.ModifiedDate Between @FromDate And @ToDate And vas.DeletedDate Is Null
			GROUP BY vas.ActivityID, ActivityDate, Activity, OneTimeVolunteers
			ORDER BY ActivityDate

proc_GetVolunteerActivity
CREATE PROCEDURE dbo.proc_GetVolunteerActivity
	(@ActivityID INT)
	AS
	SELECT Activity, ActivityDate, OneTimeVolunteers, OneTimeHours, ISNULL(va.Hours, 0) AS Hours, CreatedDate, CreatedBy,
		ModifiedDate, ModifiedBy, ISNULL(va.StaffID, 0) AS StaffID
	FROM VolunteerActivities vas LEFT OUTER JOIN VolunteerActivity va ON vas.ActivityID = va.ActivityID
	WHERE vas.ActivityID = @ActivityID

proc_GetVolunteers
CREATE PROCEDURE dbo.proc_GetVolunteers
	AS
	DECLARE @True BIT, @False BIT
	SET @True = 1 SET @False = 0
	SELECT StaffID, StaffName = CASE
		WHEN DateLeft IS NULL THEN LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		ELSE '*' + LastName + ', ' + FirstName + CASE
			WHEN LEN(MI) = 1 THEN ' ' + MI + '.'
			ELSE ''
			END
		END,
		IsCurrent = CASE WHEN DateLeft IS NULL THEN @True ELSE @False END
	FROM Staff WHERE Status = 2 AND DeletedDate IS NULL
	ORDER BY LastName, FirstName, MI

proc_InsertAbuser
CREATE PROCEDURE dbo.proc_InsertAbuser  
	(@FirstName VARCHAR(50),@LastName VARCHAR(50),@MI CHAR(1), @Sex CHAR(1), @DOB SMALLDATETIME, @EthnicityID INT, 
	@TribeID INT,@UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @AbuserID INT OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	INSERT INTO Abusers (FirstName, LastName, MI, Sex, DOB, EthnicityID, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)  
	Values  
	(@FirstName, @LastName, @MI,  @Sex, @DOB, @EthnicityID, @GetDate, @UserName, @GetDate, @UserName)
	SELECT @AbuserID = SCOPE_IDENTITY()
	IF @EthnicityID IN (7,8) AND @TribeID > 0
		INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@AbuserID, 3, @TribeID)

proc_InsertAlias
CREATE PROCEDURE dbo.proc_InsertAlias
	(@ParticipantID INT, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50),
	 @Username VARCHAR(50),	@GetDate DATETIME OUTPUT, @AliasID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Aliases (ParticipantID, FirstName, MI, LastName, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
		Values (@ParticipantID, @FirstName, @MI, @LastName, @UserName, @GetDate, @UserName, @GetDate)
	SELECT @AliasID = SCOPE_IDENTITY()
	RETURN

proc_InsertBed
CREATE PROCEDURE dbo.proc_InsertBed
	(@ShelterID INT, @Description VARCHAR(50), @IsCrib BIT, @ServiceStart SMALLDATETIME, @ServiceEnd SMALLDATETIME, 
	@UserName VARCHAR(50), @BedID INT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Beds
	(ShelterID, Description, IsCrib, ServiceStart, ServiceEnd, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
	Values
	(@ShelterID, @Description, @IsCrib, @ServiceStart, @ServiceEnd, @GetDate, @UserName, @GetDate, @UserName)
	SELECT @BedID = SCOPE_IDENTITY()
	RETURN

proc_InsertCallService
CREATE PROCEDURE dbo.proc_InsertCallService
	(@SessionID INT OUTPUT, @CallID INT, @ProgramID INT, @ServiceID INT,
	@FocusID INT, @SessionHours FLOAT, @NumberStaff INT)
	AS
	INSERT INTO CallServices
		(CallID, ProgramID, ServiceID, FocusID, SessionHours, NumberStaff)
		VALUES
		(@CallID, @ProgramID, @ServiceID, @FocusID, @SessionHours, @NumberStaff)
	SELECT @SessionID = SCOPE_IDENTITY()

proc_InsertCampus
CREATE PROCEDURE dbo.proc_InsertCampus
	(@CampusName VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT,
	 @CampusID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Campuses
	(CampusName, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
	Values
	(@CampusName, @IsCurrent, @UserName, @GetDate, @UserName, @GetDate)
	SELECT @CampusID = SCOPE_IDENTITY()
	RETURN

proc_InsertChild
CREATE PROCEDURE dbo.proc_InsertChild  
	(@ParticipantID INT, @FirstName VARCHAR(50),@LastName VARCHAR(50),@MI CHAR(1), @Sex CHAR(1), @DOB SMALLDATETIME, 
	@EthnicityID INT, @TribeID INT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @ChildID INT OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	INSERT INTO Children (ParticipantID, EthnicityID, FirstName, LastName, MI,  Sex, DOB, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)  
	Values (@ParticipantID, @EthnicityID, @FirstName, @LastName, @MI,  @Sex, @DOB, GetDate(), @UserName, GetDate(), @UserName)
	SELECT @ChildID = SCOPE_IDENTITY()
	IF @EthnicityID IN (7,8) AND @TribeID > 0
		INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@ChildID, 2, @TribeID)

proc_InsertChildAbsence
CREATE PROCEDURE dbo.proc_InsertChildAbsence
	(@ChildIntakeID INT, @DateOut SMALLDATETIME, @DateReturn SMALLDATETIME)
	AS
	INSERT INTO ChildAbsences
	(ChildIntakeID, DateOut, DateReturn)
	Values
	(@ChildIntakeID, @DateOut, @DateReturn)
	RETURN

proc_InsertChildAlias
CREATE PROCEDURE dbo.proc_InsertChildAlias
	(@ChildID INT, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50),
	 @Username VARCHAR(50),	@GetDate DATETIME OUTPUT, @AliasID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO ChildAliases (ChildID, FirstName, MI, LastName, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
		Values (@ChildID, @FirstName, @MI, @LastName, @UserName, @GetDate, @UserName, @GetDate)
	SELECT @AliasID = SCOPE_IDENTITY()

proc_InsertClientSession
CREATE PROCEDURE dbo.proc_InsertClientSession
	(@ClientID INT, @ClientTypeID INT, @SessionID INT, @IntakeID INT)
	AS
	INSERT INTO ClientSessions
	(ClientID, ClientTypeID, SessionID, IntakeID)
	Values
	(@ClientID, @ClientTypeID, @SessionID, @IntakeID)
	RETURN

proc_InsertCredential
CREATE PROCEDURE dbo.proc_InsertCredential
	(@CredentialID INT OUTPUT, @Credential VARCHAR(50), @Frequency INT, @IsSubject BIT,
	 @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Credentials 
		(Credential, Frequency, IsSubject, IsCurrent, CreatedDate, CreatedBy, ModifiedBy)
		Values
		(@Credential, @Frequency, @IsSubject, @IsCurrent, @GetDate, @UserName, @UserName)
	SELECT @CredentialID = SCOPE_IDENTITY()
	RETURN

proc_InsertEmerContact
CREATE PROCEDURE dbo.proc_InsertEmerContact  
	(@ParticipantID INT, @ContactName VARCHAR(100),@Relationship VARCHAR(50), @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(50), 
	@Zip VARCHAR(10),@Phone VARCHAR(15), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @EmerContactID INT OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	INSERT INTO EmerContacts (ParticipantID, ContactName, Relationship, Address, City, State, Zip, Phone, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)  
	Values (@ParticipantID, @ContactName, @Relationship, @Address, @City,  @State, @Zip, @Phone, @GetDate, @UserName, @GetDate, @UserName)  
	SELECT @EmerContactID = SCOPE_IDENTITY() 
	RETURN

proc_InsertFocus
CREATE PROCEDURE dbo.proc_InsertFocus
	(@FocusID INT OUTPUT, @Focus VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Focus
	(Focus, IsCurrent, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
	Values
	(@Focus, @IsCurrent, @UserName, @UserName, @GetDate, @GetDate)
	SELECT @FocusID = SCOPE_IDENTITY()
	RETURN

proc_InsertFocusService
CREATE PROCEDURE dbo.proc_InsertFocusService
	(@FocusID INT, @ServiceID INT)
	AS
	INSERT INTO ServiceFocus
	(FocusID, ServiceID)
	Values
	(@FocusID, @ServiceID)
	RETURN

proc_InsertGoal
CREATE PROCEDURE dbo.proc_InsertGoal
	(@GoalID INT OUTPUT, @GetDate DATETIME OUTPUT, @Goal VARCHAR(50), @UserName VARCHAR(50))
	AS
	SELECT @GetDate = GETDATE()
	SELECT @GoalID = 1 + (SELECT Max(GoalID) FROM Goals)	
	INSERT INTO Goals
	(GoalID, Goal, CreatedBy, ModifiedBy, CreatedDate)
	VALUES
	(@GoalID, @Goal, @UserName, @UserName, @GetDate)

proc_InsertGrant
CREATE PROCEDURE dbo.proc_InsertGrant
	(@GrantID INT OUTPUT, @GrantorID INT, @ContractNumber VARCHAR(50), @GrantStart SMALLDATETIME, 
	@GrantEnd SMALLDATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @Prorate FLOAT = 1)
	AS
	SELECT @GetDate = getdate() 
	INSERT INTO Grants
	(GrantorID, ContractNumber, GrantStart, GrantEnd, Prorate, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
	Values
	(@GrantorID, @ContractNumber, @GrantStart, @GrantEnd, @Prorate, @UserName, @UserName, @GetDate, @GetDate)
	SELECT @GrantID = SCOPE_IDENTITY()

proc_InsertGrantSurveys
CREATE PROCEDURE dbo.proc_InsertGrantSurveys
	(@SurveyID INT, @GrantID INT)
	AS
	INSERT INTO GrantSurveys
	(GrantID, SurveyID)
	VALUES
	(@GrantID, @SurveyID)
	RETURN

proc_InsertGrantTarget
CREATE PROCEDURE dbo.proc_InsertGrantTarget
	(@GrantID INT, @TargetID INT, @TargetTypeID INT)
	AS
	INSERT INTO GrantTargets
	(GrantID, TargetID, TargetTypeID)
	Values
	(@GrantID, @TargetID, @TargetTypeID)
	RETURN

proc_InsertHotlineReferral
CREATE PROCEDURE dbo.proc_InsertHotlineReferral  
	(@CallID INT, @HotlineReferralID INT)  
	AS  
	INSERT INTO HotlineReferrals (CallID, HotlineReferralID)  
	Values  
	(@CallID, @HotlineReferralID)  
	RETURN

proc_InsertIntakeBed
CREATE PROCEDURE dbo.proc_InsertIntakeBed
	(@IntakeID INT, @ClientTypeID INT, @BedID INT, @DateIn SMALLDATETIME, @DateOut SMALLDATETIME,
	 @UserName VARCHAR(50))
	AS
	IF (SELECT TOP 1 IntakeID 
		FROM IntakeBeds 
		WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID AND DateIn = @DateIn) IS NULL
		BEGIN
			INSERT INTO IntakeBeds
				(IntakeID, ClientTypeID, BedID, DateIn, DateOut, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
				Values
				(@IntakeID, @ClientTypeID, @BedID, @DateIn, @DateOut, @UserName, @UserName, getdate(), getdate())
		END
	ELSE
		BEGIN
			UPDATE IntakeBeds
			SET BedID = @BedID, DateOut = @DateOut, ModifiedBy = @UserName, ModifiedDate = GETDATE()
			WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID AND DateIn = @DateIn
		END

proc_InsertIntakePhase
CREATE PROCEDURE dbo.proc_InsertIntakePhase
	(@IntakeID INT, @PhaseID INT, @BeginDate SMALLDATETIME, @ProjectedEnd SMALLDATETIME, @CompletedDate SMALLDATETIME)
	AS
	INSERT INTO IntakePhase (IntakeID, PhaseID, BeginDate, ProjectedEnd, CompletedDate)
		Values (@IntakeID, @PhaseID, @BeginDate, @ProjectedEnd, @CompletedDate)

proc_InsertIntakeStaff
CREATE Procedure dbo.proc_InsertIntakeStaff
	(@IntakeID INT, @StaffID INT, @StaffRole VARCHAR(50))
	AS
	INSERT INTO IntakeStaff (StaffID, IntakeID, StaffRole) Values (@StaffID, @IntakeID, @StaffRole)

proc_InsertIntakeTask
CREATE PROCEDURE dbo.proc_InsertIntakeTask
	(@IntakeID INT, @TaskID INT,  @CompletedDate SMALLDATETIME)
	AS
	INSERT INTO IntakeTasks (IntakeID, TaskID, CompletedDate)
		Values (@IntakeID, @TaskID, @CompletedDate)

proc_InsertIntakeVictimType
-- Add a procedure for inserting VictimType values into the IntakeVictimType table
CREATE Procedure dbo.proc_InsertIntakeVictimType
	(@IntakeID INT, @VictimTypeID INT)
	AS
	INSERT INTO IntakeVictimType (IntakeID, VictimTypeID) Values (@IntakeID, @VictimTypeID)

proc_InsertNarrativeResponse
CREATE PROCEDURE dbo.proc_InsertNarrativeResponse
	(@NarrativeID INT, @QuestionnaireID INT, @Narrative VARCHAR(1000))
	AS
	INSERT INTO NarrativeResponses
	(NarrativeID, QuestionnaireID, Narrative)
	VALUES
	(@NarrativeID, @QuestionnaireID, @Narrative)
	RETURN

proc_InsertNote
CREATE PROCEDURE dbo.proc_InsertNote
	(@NoteID INT OUTPUT, @GetDate DATETIME OUTPUT, @ClientID INT, @ClientTypeID INT,
	@NoteDate SMALLDATETIME, @Subject VARCHAR(50), @NoteText VARCHAR(2000), @UserName VARCHAR(50))
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Notes
	(ClientID, ClientTypeID, NoteDate, Subject, NoteText, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
	Values
	(@ClientID, @ClientTypeID, @NoteDate, @Subject, @NoteText, @GetDate, @UserName, @GetDate, @UserName)
	SELECT @NoteID = SCOPE_IDENTITY()

proc_InsertParticipantFile
CREATE PROCEDURE dbo.proc_InsertParticipantFile
	(@FileID INT OUTPUT, @ParticipantID INT, @FileData VARBINARY(MAX), @ShortFileName VARCHAR(256), 
	@FileSize VARCHAR(50), @Extension VARCHAR(10), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	DELETE FROM ParticipantFiles WHERE FileID = @FileID
	SELECT @GetDate = GETDATE()
	INSERT INTO ParticipantFiles
		(ParticipantID, FileData, ShortFileName, FileSize, Extension, CreatedBy, CreatedDate)
		VALUES
		(@ParticipantID, @FileData, @ShortFileName, @FileSize, @Extension, @UserName, @GetDate)
	SELECT @FileID = SCOPE_IDENTITY()

proc_InsertPet
CREATE PROCEDURE dbo.proc_InsertPet
	(@IntakeID INT, @PetTypeID INT, @Name VARCHAR(100), @Breed VARCHAR(100),
	@IsVaccinated BIT, @IsAbused BIT, @RetainedOnExit BIT)
	AS
	INSERT INTO Pets (IntakeID, PetTypeID, Name, Breed, IsVaccinated, IsAbused, RetainedOnExit)
		VALUES (@IntakeID, @PetTypeID, @Name, @Breed, @IsVaccinated, @IsAbused, @RetainedOnExit)

proc_InsertPresentationTopic
CREATE PROCEDURE dbo.proc_InsertPresentationTopic
	(@PresentationID INT, @TopicID INT)
	AS
	INSERT INTO PresentationTopics
	(PresentationID, TopicID)
	Values
	(@PresentationID, @TopicID)
	RETURN

proc_InsertProgram
CREATE PROCEDURE dbo.proc_InsertProgram
	(@ProgramID INT OUTPUT, @Program VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Programs
	(Program, IsCurrent, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
	Values
	(@Program, @IsCurrent, @UserName, @UserName, @GetDate, @GetDate)
	SELECT @ProgramID = SCOPE_IDENTITY()

proc_InsertProgramService
CREATE PROCEDURE dbo.proc_InsertProgramService
	(@ProgramID INT, @ServiceID INT)
	AS
	INSERT INTO ProgramServices
	(ProgramID, ServiceID)
	Values
	(@ProgramID, @ServiceID)
	RETURN

proc_InsertQuestionnaire
CREATE PROCEDURE dbo.proc_InsertQuestionnaire
	(@SurveyID INT, @IntakeID INT, @CompletedDate DATETIME, @ControlNumber VARCHAR(50), @ClientTypeID INT,
	@UserName VARCHAR(50), @QuestionnaireID INT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
		INSERT INTO Questionnaires
		(SurveyID, IntakeID, CompletedDate, ControlNumber, ClientTypeID, CreatedDate, ModifiedDate, CreatedBy, ModifiedBy)
		VALUES
		(@SurveyID, @IntakeID, @CompletedDate, @ControlNumber, @ClientTypeID, @GetDate, @GetDate, @UserName, @UserName)
		SELECT @QuestionnaireID = SCOPE_IDENTITY()

proc_InsertQuestionResponses
CREATE PROCEDURE dbo.proc_InsertQuestionResponses
	(@QuestionID INT, @QuestionnaireID INT, @Response INT)
	AS
	INSERT INTO QuestionResponses
	(QuestionID, QuestionnaireID, Response)
	VALUES
	(@QuestionID, @QuestionnaireID, @Response)
	RETURN

proc_InsertReferral
CREATE PROCEDURE dbo.proc_InsertReferral
	(@ClientID INT, @ClientTypeID INT, @IntakeID INT, @ReferralTypeID INT, @ReferralDate SMALLDATETIME, 
	 @NumberReferrals INT, @Agency VARCHAR(50), @UserName VARCHAR(50), @ReferralID INT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Referrals
	(ClientID, ClientTypeID, IntakeID, ReferralTypeID, ReferralDate, NumberReferrals, Agency, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
	Values
	(@ClientID, @ClientTypeID, @IntakeID, @ReferralTypeID, @ReferralDate, @NumberReferrals, @Agency, @GetDate, @UserName, @GetDate, @UserName)
	SELECT @ReferralID = SCOPE_IDENTITY()
	RETURN

proc_InsertReleaseEntity
CREATE PROCEDURE dbo.proc_InsertReleaseEntity
	(@ReleaseID INT, @EntityID INT)
	AS
	INSERT INTO ReleaseEntities (ReleaseID, EntityID) VALUES (@ReleaseID, @EntityID)

proc_InsertRHBA
CREATE PROCEDURE dbo.proc_InsertRHBA
	(@ParticipantID INT, @RhbaEligible BIT, @EnrollmentStatus VARCHAR(50), @Title19Eligible BIT, 
	@DiagnosticCode VARCHAR(50), @Diagnosis VARCHAR(250), @Comments VARCHAR(250), 
	@T19ApplicationStatus VARCHAR(50), @T19ApplicationDate SMALLDATETIME,
	@AhcccsID VARCHAR(50), @CisID VARCHAR(15))
	AS
	INSERT INTO RHBA
	(ParticipantID, RhbaEligible, EnrollmentStatus, Title19Eligible, DiagnosticCode, 
	Diagnosis, Comments, T19ApplicationStatus, T19ApplicationDate, AhcccsID, CisID)
	VALUES
	(@ParticipantID, @RhbaEligible, @EnrollmentStatus, @Title19Eligible, @DiagnosticCode, 
	@Diagnosis, @Comments, @T19ApplicationStatus, @T19ApplicationDate, @AhcccsID, @CisID)

proc_InsertRoom
CREATE PROCEDURE dbo.proc_InsertRoom
	(@ShelterID INT, @RoomNumber VARCHAR(50), @ServiceStart SMALLDATETIME, @ServiceEnd SMALLDATETIME, 
	@UserName VARCHAR(50), @RoomID INT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Rooms
	(ShelterID, RoomNumber, ServiceStart, ServiceEnd, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
	Values
	(@ShelterID, @RoomNumber, @ServiceStart, @ServiceEnd, @GetDate, @UserName, @GetDate, @UserName)
	SELECT @RoomID = SCOPE_IDENTITY()
	RETURN

proc_InsertRoomBedAssignment
CREATE PROCEDURE dbo.proc_InsertRoomBedAssignment
	(@BedID INT, @RoomID INT, @DateAssigned SMALLDATETIME, @DateMoved SMALLDATETIME,
	 @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @RoomBedAssignmentID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO RoomBedAssignments
		(BedID, RoomID, DateAssigned, DateMoved, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
	VALUES
		(@BedID, @RoomID, @DateAssigned, @DateMoved, @UserName, @GetDate, @UserName, @GetDate)
	SELECT @RoomBedAssignmentID = SCOPE_IDENTITY()
	RETURN

proc_InsertSessionNote
CREATE PROCEDURE dbo.proc_InsertSessionNote
	(@SessionID INT, @StartTime VARCHAR(15), @EndTime VARCHAR(15), @Note VARCHAR(4000))
	AS
	INSERT INTO SessionNotes 
		(SessionID, StartTime, EndTime, Note)
	VALUES 
		(@SessionID, @StartTime, @EndTime, @Note)

proc_InsertShelter
CREATE PROCEDURE dbo.proc_InsertShelter
	(@ShelterName VARCHAR(100), @HousingTypeID INT, @IsCurrent BIT, @IsLicensed BIT, @ShelterTypeID INT,                     
	 @Residential BIT, @NonResidential BIT, @Hotline BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT,
	 @CampusID INT, @ShelterID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO Shelters
	(CampusID, ShelterName, HousingTypeID, IsLicensed, IsCurrent, ShelterTypeID, Residential, NonResidential, Hotline,
	CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
	Values
	(@CampusID, @ShelterName, @HousingTypeID, @IsLicensed, @IsCurrent, @ShelterTypeID, @Residential, @NonResidential, @Hotline,
	@UserName, @UserName, @GetDate, @GetDate)
	SELECT @ShelterID = SCOPE_IDENTITY()
	RETURN

proc_InsertStaffCallService
CREATE PROCEDURE dbo.proc_InsertStaffCallService
	(@SessionID INT, @StaffID INT)
	AS
	INSERT INTO StaffCallService
		(SessionID, StaffID)
		VALUES
		(@SessionID, @StaffID)

proc_InsertStaffMember
CREATE PROCEDURE dbo.proc_InsertStaffMember
	(@StaffID INT OUTPUT, @FirstName VARCHAR(50), @MI VARCHAR(1), @LastName VARCHAR(50), @Title VARCHAR(50), 
	@ServiceProvider BIT, @Status INT, @DateLeft DATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate() 
	INSERT INTO Staff
	(FirstName, MI, LastName, Title, ServiceProvider, Status, DateLeft, CreatedBy, ModifiedBy, CreatedDate)
	Values
	(@FirstName, @MI, @LastName, @Title, @ServiceProvider, @Status, @DateLeft, @UserName, @UserName, @GetDate)
	SELECT @StaffID = SCOPE_IDENTITY()
	RETURN

proc_InsertStaffMemberExt
CREATE PROCEDURE dbo.proc_InsertStaffMemberExt
	(@StaffID INT, @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(50), @Zip VARCHAR(10),
	@WorkPhone VARCHAR(50), @Ext VARCHAR(10), @MobilePhone VARCHAR(50), @HomePhone VARCHAR(50),
	@Email VARCHAR(100), @DOB SMALLDATETIME, @HireDate SMALLDATETIME, @LastEvalDate SMALLDATETIME,
	@Rehire BIT, @RehireComment VARCHAR(100), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	DELETE FROM StaffExt WHERE StaffID = @StaffID
	INSERT INTO StaffExt
	(StaffID, Address, City, State, Zip, WorkPhone, Ext, MobilePhone, HomePhone,
	 Email, DOB, HireDate, LastEvalDate, Rehire, RehireComment, CreatedBy, ModifiedBy, CreatedDate)
	Values
	(@StaffID, @Address, @City, @State, @Zip, @Workphone, @Ext, @MobilePhone, @HomePhone,
	 @Email, @DOB, @HireDate, @LastEvalDate, @Rehire, @RehireComment, @UserName, @UserName, @GetDate)

proc_InsertStaffPresentation
CREATE PROCEDURE dbo.proc_InsertStaffPresentation
	(@PresentationID INT, @StaffID INT)
	AS
	INSERT INTO StaffPresentations
	(PresentationID, StaffID)
	Values
	(@PresentationID, @StaffID)
	RETURN

proc_InsertStaffReferral
CREATE PROCEDURE dbo.proc_InsertStaffReferral
	(@ReferralID INT, @StaffID INT)
	AS
	INSERT INTO	StaffReferrals
	(ReferralID, StaffID)
	Values
	(@ReferralID, @StaffID)

proc_InsertStaffRequirement
CREATE PROCEDURE dbo.proc_InsertStaffRequirement
	(@StaffID INT, @RequirementID INT, @DueDate SMALLDATETIME, @CompletedDate SMALLDATETIME)
	AS
	INSERT INTO StaffRequirements
		(StaffID, RequirementID, DueDate, CompletedDate)
		Values
		(@StaffID, @RequirementID, @DueDate, @CompletedDate)
	RETURN

proc_InsertStaffSession
CREATE PROCEDURE dbo.proc_InsertStaffSession
	(@SessionID INT, @StaffID INT)
	AS
	INSERT INTO	StaffSessions
	(SessionID, StaffID)
	Values
	(@SessionID, @StaffID)
	RETURN

proc_InsertStaffTraining
CREATE PROCEDURE dbo.proc_InsertStaffTraining
	(@StaffID INT, @SessionID INT)
	AS
	INSERT INTO StaffTraining
		(StaffID, SessionID)
		Values
		(@StaffID, @SessionID)
	RETURN

proc_InsertSurvey
CREATE PROCEDURE dbo.proc_InsertSurvey
	(@SurveyName VARCHAR(50), @IsCurrent BIT, @IsAnonymous BIT, @UserName VARCHAR(50), @SurveyID INT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	IF NOT EXISTS (SELECT TOP 1 SurveyID FROM Surveys WHERE SurveyName = @SurveyName)
		BEGIN
			INSERT INTO Surveys
			(SurveyName, IsCurrent, IsAnonymous, CreatedDate, ModifiedDate, CreatedBy, ModifiedBy)
			VALUES
			(@SurveyName, @IsCurrent, @IsAnonymous, @GetDate, @GetDate, @UserName, @UserName)
			SELECT @SurveyID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			SELECT @SurveyID = -1 -- Output value indicates Survey Name already exists
		END

proc_InsertSurveyNarrative
CREATE PROCEDURE dbo.proc_InsertSurveyNarrative
	(@SurveyID INT, @Description VARCHAR(500))
	AS
	INSERT INTO SurveyNarratives 
	(SurveyID, Description)
	VALUES 
	(@SurveyID, @Description)
	RETURN

proc_InsertSurveyQuestions
CREATE PROCEDURE dbo.proc_InsertSurveyQuestions
	(@SurveyID INT, @QuestionID INT, @QuestionNumber INT)
	AS
	INSERT INTO SurveyQuestions
	(QuestionID, SurveyID, QuestionNumber)
	VALUES
	(@QuestionID, @SurveyID, @QuestionNumber)

proc_InsertTangibleGoods
CREATE PROCEDURE dbo.proc_InsertTangibleGoods
	(@SessionID INT, @GoodTypeID INT, @Quantity INT)
	AS
	INSERT INTO TangibleGoods
		(SessionID, GoodTypeID, Quantity)
		VALUES
		(@SessionID, @GoodTypeID, @Quantity)

proc_InsertTopic
CREATE PROCEDURE dbo.proc_InsertTopic
	(@TopicID INT OUTPUT, @Topic VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50))
	AS
	INSERT INTO xTopic
		(Topic, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
		Values
		(@Topic, @IsCurrent, @UserName, getdate(), @UserName, getdate())
	SELECT @TopicID = SCOPE_IDENTITY()

proc_InsertTrip
CREATE PROCEDURE dbo.proc_InsertTrip
	(@SessionID INT, @PurposeID INT = 1,  @Destination VARCHAR(100), @OneWay BIT,
	@MilesOneWay FLOAT, @DestinationCountyID INT, @VehicleID INT)
	AS
	INSERT INTO Trips 
		(TripID, PurposeID, Destination, OneWay, MilesOneWay, DestinationCountyID, VehicleID) 
		Values
		(@SessionID, @PurposeID, @Destination, @OneWay, @MilesOneWay, @DestinationCountyID, @VehicleID);

proc_InsertVolunteer
CREATE PROCEDURE dbo.proc_InsertVolunteer
	(@ActivityID INT, @StaffID INT, @Hours FLOAT)
	AS
	INSERT INTO VolunteerActivity (ActivityID, StaffID, Hours)
		Values (@ActivityID, @StaffID, @Hours)

proc_LinkIntakes
CREATE PROCEDURE dbo.proc_LinkIntakes
	(@ParticipantID INT, @GainingIntakeID INT, @OriginIntakeID INT)
	AS
	DELETE FROM LinkedIntakes WHERE ParticipantID = @ParticipantID AND OriginIntakeID = @OriginIntakeID
	INSERT INTO LinkedIntakes (ParticipantID, OriginIntakeID, GainingIntakeID)
		VALUES (@ParticipantID, @OriginIntakeID, @GainingIntakeID)

proc_LinkIntakeToCall
CREATE PROCEDURE dbo.proc_LinkIntakeToCall
	(@IntakeID INT, @CallID INT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	INSERT INTO IntakeCalls
		(IntakeID, CallID, CreatedBy, CreatedDate)
		Values
		(@IntakeID, @CallID, @UserName, @GetDate)
	RETURN

proc_LookupAddNewEntry
CREATE PROCEDURE dbo.proc_LookupAddNewEntry
	(@DictionaryKey VARCHAR(100), @NewEntry VARCHAR(100), @UserName VARCHAR(50))
	AS
	IF @DictionaryKey = 'Language'
		BEGIN
			IF (SELECT TOP 1 LanguageID FROM xLanguage WHERE Language = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xLanguage (Language, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT LanguageID, Language FROM xLanguage WHERE DeletedDate IS NULL ORDER BY Language
				END
		END
	IF @DictionaryKey = 'Location'
		BEGIN
			IF (SELECT TOP 1 LocationID FROM xLocation WHERE Location = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xLocation (Location, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT LocationID, Location FROM xLocation WHERE DeletedDate IS NULL ORDER BY Location
				END
		END
	IF @DictionaryKey = 'Tribe'
		BEGIN
			IF (SELECT TOP 1 TribeID FROM xTribe WHERE Tribe = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xTribe (Tribe, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT TribeID, Tribe FROM xTribe WHERE DeletedDate IS NULL ORDER BY Tribe
				END
		END
	IF @DictionaryKey = 'Religion'
		BEGIN
			IF (SELECT TOP 1 ReligionID FROM xReligion WHERE Religion = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xReligion (Religion, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ReligionID, Religion FROM xReligion WHERE DeletedDate IS NULL ORDER BY Religion
				END
		END
	IF @DictionaryKey = 'Vehicle'
		BEGIN
			IF (SELECT TOP 1 VehicleID FROM Vehicles WHERE Vehicle = @NewEntry) IS NULL
				BEGIN
					INSERT INTO Vehicles (Vehicle, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT VehicleID, Vehicle FROM Vehicles WHERE DeletedDate IS NULL ORDER BY Vehicle
				END
		END
	IF @DictionaryKey = 'TripPurpose'
		BEGIN
			IF (SELECT TOP 1 PurposeID FROM xTripPurpose WHERE Purpose = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xTripPurpose (Purpose, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT PurposeID, Purpose FROM xTripPurpose WHERE DeletedDate IS NULL ORDER BY Purpose
				END
		END
	IF @DictionaryKey = 'Task'
		BEGIN
			IF (SELECT TOP 1 TaskID FROM xTask WHERE Task = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xTask (Task, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT TaskID, Task FROM xTask WHERE DeletedDate IS NULL ORDER BY Task
				END
		END
	IF @DictionaryKey = 'Topic'
		BEGIN
			IF (SELECT TOP 1 TopicID FROM xTopic WHERE Topic = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xTopic (Topic, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT TopicID, Topic FROM xTopic WHERE DeletedDate IS NULL ORDER BY Topic
				END
		END
	IF @DictionaryKey = 'PetType'
		BEGIN
			IF (SELECT TOP 1 PetTypeID FROM xPetType WHERE PetType = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xPetType (PetType) VALUES (@NewEntry);
					SELECT PetTypeID, PetType FROM xPetType ORDER BY PetType
				END
		END
	IF @DictionaryKey = 'ServiceLocation'
		BEGIN
			IF (SELECT TOP 1 LocationID FROM xServiceLocation WHERE Location = @NewEntry) IS NULL
				BEGIN
					INSERT INTO xServiceLocation (Location, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate) 
						VALUES (@NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT LocationID, Location FROM xServiceLocation ORDER BY Location
				END
		END
	IF @@ERROR = 0 
		BEGIN
			RETURN SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			RETURN 0
		END

proc_LookupAddOtherEntry
CREATE PROCEDURE dbo.proc_LookupAddOtherEntry
	(@DictionaryKey VARCHAR(100), @NewEntry VARCHAR(100), @UserName VARCHAR(50))
	AS
	DECLARE @MaxID INT
	IF @DictionaryKey = 'AbuserRelationship'
		BEGIN
			IF (SELECT TOP 1 AbuserRelationshipID FROM xAbuserRelationship WHERE AbuserRelationship = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(AbuserRelationshipID) FROM xAbuserRelationship)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xAbuserRelationship(AbuserRelationshipID, AbuserRelationship, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT AbuserRelationshipID, AbuserRelationship FROM xAbuserRelationship WHERE AbuserRelationshipID < 101 UNION ALL
					SELECT AbuserRelationshipID, AbuserRelationship FROM xAbuserRelationship WHERE AbuserRelationshipID > 100;
				END
		END
	IF @DictionaryKey = 'CallSubject'
		BEGIN
			IF (SELECT TOP 1 CallSubjectID FROM xCallSubject WHERE CallSubject = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(CallSubjectID) FROM xCallSubject)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xCallSubject(CallSubjectID, CallSubject,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT CallSubjectID, CallSubject FROM xCallSubject WHERE CallSubjectID < 101 UNION ALL
					SELECT CallSubjectID, CallSubject FROM xCallSubject WHERE CallSubjectID > 100;
				END
		END
	IF @DictionaryKey = 'Ethnicity'
		BEGIN
			IF (SELECT TOP 1 EthnicityID FROM xEthnicity WHERE Ethnicity = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(EthnicityID) FROM xEthnicity)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xEthnicity (EthnicityID, Ethnicity, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT EthnicityID, Ethnicity FROM xEthnicity WHERE EthnicityID < 101 UNION ALL
					SELECT EthnicityID, Ethnicity FROM xEthnicity WHERE EthnicityID > 100; 
				END
		END
	IF @DictionaryKey = 'ExitDestination'
		BEGIN
			IF (SELECT TOP 1 ExitDestinationID FROM xExitDestination WHERE ExitDestination = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ExitDestinationID) FROM xExitDestination)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xExitDestination (ExitDestinationID, ExitDestination,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ExitDestinationID, ExitDestination FROM xExitDestination WHERE ExitDestinationID < 101 UNION ALL
					SELECT ExitDestinationID, ExitDestination FROM xExitDestination WHERE ExitDestinationID > 100;
				END
		END
	IF @DictionaryKey = 'ExitHousing'
		BEGIN
			IF (SELECT TOP 1 ExitHousingID  FROM xExitHousing WHERE ExitHousing = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ExitHousingID) FROM xExitHousing)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xExitHousing(ExitHousingID, ExitHousing,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ExitHousingID, ExitHousing FROM xExitHousing WHERE ExitHousingID < 101 UNION ALL
					SELECT ExitHousingID, ExitHousing FROM xExitHousing WHERE ExitHousingID > 100;
				END
		END
	IF @DictionaryKey = 'ExitReason'
		BEGIN
			IF (SELECT TOP 1 ExitReasonID FROM xExitReason WHERE ExitReason = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ExitReasonID) FROM xExitReason)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xExitReason(ExitReasonID, ExitReason,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ExitReasonID, ExitReason FROM xExitReason WHERE ExitReasonID < 101 UNION ALL
					SELECT ExitReasonID, ExitReason FROM xExitReason WHERE ExitReasonID > 100;
				END
		END
	IF @DictionaryKey = 'HotlineReferral'
		BEGIN
			IF (SELECT TOP 1 HotlineReferralID FROM xHotlineReferral WHERE HotlineReferral = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(HotlineReferralID) FROM xHotlineReferral)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xHotlineReferral(HotlineReferralID, HotlineReferral,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT HotlineReferralID, HotlineReferral FROM xHotlineReferral WHERE HotlineReferralID < 101 UNION ALL
					SELECT HotlineReferralID, HotlineReferral FROM xHotlineReferral WHERE HotlineReferralID > 100;
				END
		END
	IF @DictionaryKey = 'ReasonDenied'
		BEGIN
			IF (SELECT TOP 1 ReasonDeniedID FROM xReasonDenied WHERE ReasonDenied = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ReasonDeniedID) FROM xReasonDenied)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xReasonDenied(ReasonDeniedID, ReasonDenied,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ReasonDeniedID, ReasonDenied FROM xReasonDenied WHERE ReasonDeniedID < 101 UNION ALL
					SELECT ReasonDeniedID, ReasonDenied FROM xReasonDenied WHERE ReasonDeniedID > 100;
				END
		END
	IF @DictionaryKey = 'ReferralSource'
		BEGIN
			IF (SELECT TOP 1 ReferralSourceID FROM xReferralSource WHERE ReferralSource = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ReferralSourceID) FROM xReferralSource)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xReferralSource(ReferralSourceID, ReferralSource,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ReferralSourceID, ReferralSource FROM xReferralSource WHERE ReferralSourceID < 101 UNION ALL
					SELECT ReferralSourceID, ReferralSource FROM xReferralSource WHERE ReferralSourceID > 100;
				END
		END
	IF @DictionaryKey = 'ReferralType'
		BEGIN
			IF (SELECT TOP 1 ReferralTypeID FROM xReferralType WHERE ReferralType = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(ReferralTypeID) FROM xReferralType)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xReferralType(ReferralTypeID, ReferralType,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT ReferralTypeID, ReferralType FROM xReferralType WHERE ReferralTypeID < 101 UNION ALL
					SELECT ReferralTypeID, ReferralType FROM xReferralType WHERE ReferralTypeID > 100;
				END
		END
	IF @DictionaryKey = 'PriorResidence'
		BEGIN
			IF (SELECT TOP 1 PriorResidenceID FROM xPriorResidence WHERE PriorResidence = @NewEntry) IS NULL
				BEGIN
					SET @MaxID = (SELECT MAX(PriorResidenceID) FROM xPriorResidence)
					IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
					INSERT INTO xPriorResidence(PriorResidenceID, PriorResidence,CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
						VALUES (@MaxID, @NewEntry, @UserName, @UserName, GETDATE(), GETDATE());
					SELECT PriorResidenceID, PriorResidence FROM xPriorResidence WHERE PriorResidenceID < 101 UNION ALL
					SELECT PriorResidenceID, PriorResidence FROM xPriorResidence WHERE PriorResidenceID > 100;
				END
		END
	IF @@ERROR = 0
		BEGIN
			RETURN @MaxID
		END
	ELSE
		BEGIN
			RETURN 0
		END

proc_MapService
-- Update the procedures for saving/deleting mapping of shelter service to grantor service
-- using ServiceFocusID instead of ServiceID
CREATE PROCEDURE dbo.proc_MapService
	(@ServiceFocusID INT, @GrantorServiceID INT, @GrantorID INT, @UserName VARCHAR(50), @NewMap BIT Output)
	AS
	IF EXISTS (SELECT ServiceFocusID FROM ServiceMap WHERE ServiceFocusID = @ServiceFocusID And GrantorID = @GrantorID) 
		SELECT @NewMap = 0
	ELSE
		INSERT INTO ServiceMap
		(ServiceFocusID, GrantorServiceID, GrantorID, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
		Values
		(@ServiceFocusID, @GrantorServiceID, @GrantorID, @UserName, @UserName, getdate(), getdate()) 
		SELECT @NewMap = 1

proc_MergeAbuserRelationship
CREATE PROCEDURE dbo.proc_MergeAbuserRelationship
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET AbuserRelationshipID = @TargetID WHERE AbuserRelationshipID = @SourceID
	UPDATE AbuserAlerts SET AbuserRelationshipID = @TargetID WHERE AbuserRelationshipID = @SourceID
	DELETE FROM xAbuserRelationship WHERE AbuserRelationshipID = @SourceID

proc_MergeCallSubject
CREATE PROCEDURE dbo.proc_MergeCallSubject
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Calls SET CallSubjectID = @TargetID WHERE CallSubjectID = @SourceID
	DELETE FROM xCallSubject WHERE CallSubjectID = @SourceID

proc_MergeCampus
CREATE PROCEDURE dbo.proc_MergeCampus
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Shelters Set CampusID = @TargetID WHERE CampusID = @SourceID
	DELETE FROM Campuses WHERE CampusID = @SourceID

proc_MergeChildren
CREATE PROCEDURE dbo.proc_MergeChildren
	(@FromChildID INT, @ToChildID INT, @UserName VARCHAR(50))
	AS
	UPDATE Notes SET ClientID = @ToChildID WHERE ClientID = @FromChildID And ClientTypeID = 2
	UPDATE Referrals SET ClientID = @ToChildID WHERE ClientID = @FromChildID And ClientTypeID = 2
	UPDATE ClientSessions SET ClientID = @ToChildID WHERE ClientID = @FromChildID And ClientTypeID = 2
	UPDATE ChildIntakes SET ChildID = @ToChildID WHERE ChildID = @FromChildID 
	UPDATE Children SET DeletedDate = getdate(), DeletedBy = @UserName WHERE ChildID = @FromChildID

proc_MergeCredential
CREATE PROCEDURE dbo.proc_MergeCredential
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE TrainingSessions SET SubjectID = @TargetID WHERE SubjectID = @SourceID
	DELETE FROM StaffRequirements WHERE RequirementID = @SourceID AND StaffID IN
		(SELECT StaffID FROM StaffRequirements WHERE RequirementID = @TargetID)
	UPDATE StaffRequirements SET RequirementID = @TargetID WHERE RequirementID = @SourceID
	DELETE FROM Credentials WHERE CredentialID = @SourceID

proc_MergeEthnicity
-- Fix Ethnicity merge problem when a community member is assigned the old ethnicity
CREATE PROCEDURE dbo.proc_MergeEthnicity
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Participants SET EthnicityID = @TargetID WHERE EthnicityID = @SourceID
	UPDATE Children SET EthnicityID = @TargetID WHERE EthnicityID = @SourceID
	UPDATE Abusers SET EthnicityID = @TargetID WHERE EthnicityID = @SourceID
	UPDATE CommunityMembers SET EthnicityID = @TargetID WHERE EthnicityID = @SourceID
	UPDATE AbuserAlerts SET EthnicityID = @TargetID WHERE EthnicityID = @SourceID
	DELETE FROM xEthnicity WHERE EthnicityID = @SourceID

proc_MergeExitDestination
CREATE PROCEDURE dbo.proc_MergeExitDestination
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET ExitDestinationID = @TargetID WHERE ExitDestinationID = @SourceID
	DELETE FROM xExitDestination WHERE ExitDestinationID = @SourceID

proc_MergeExitHousing
CREATE PROCEDURE dbo.proc_MergeExitHousing
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET ExitHousingID = @TargetID WHERE ExitHousingID = @SourceID
	DELETE FROM xExitHousing WHERE ExitHousingID = @SourceID

proc_MergeExitReason
CREATE PROCEDURE dbo.proc_MergeExitReason
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET ExitReasonID = @TargetID WHERE ExitReasonID = @SourceID
	DELETE FROM xExitReason WHERE ExitReasonID = @SourceID

proc_MergeFacilitator
CREATE PROCEDURE dbo.proc_MergeFacilitator
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE SessionFacilitators SET FacilitatorID = @TargetID 
		WHERE FacilitatorID = @SourceID AND SessionID NOT IN
		(SELECT SessionID FROM SessionFacilitators WHERE FacilitatorID = @TargetID)
	DELETE FROM SessionFacilitators WHERE FacilitatorID = @SourceID
	DELETE FROM Facilitators WHERE FacilitatorID = @SourceID

proc_MergeFocus
-- Change procedure for merging focus to allow merge when current focus is mapped
CREATE PROCEDURE dbo.proc_MergeFocus
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE ServiceFocus
		SET FocusID = @TargetID
		WHERE FocusID = @SourceID AND ServiceID NOT IN
			(SELECT ServiceID FROM ServiceFocus
			WHERE FocusID = @TargetID)
	UPDATE Sessions SET FocusID = @TargetID WHERE FocusID = @SourceID
	DELETE FROM ServiceMap WHERE ServiceFocusID IN
		(SELECT ServiceFocusID FROM ServiceFocus WHERE FocusID = @SourceID)
	DELETE FROM ServiceFocus WHERE FocusID = @SourceID
	DELETE FROM Focus WHERE FocusID = @SourceID

proc_MergeGoodType
CREATE PROCEDURE dbo.proc_MergeGoodType
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE TangibleGoods SET GoodTypeID = @TargetID WHERE GoodTypeID = @SourceID
	DELETE FROM xGoodType WHERE GoodTypeID = @SourceID

proc_MergeHotlineReferral
CREATE PROCEDURE dbo.proc_MergeHotlineReferral
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE HotlineReferrals SET HotlineReferralID = @TargetID WHERE HotlineReferralID = @SourceID
	DELETE FROM xHotlineReferral WHERE HotlineReferralID = @SourceID

proc_MergeLanguage
CREATE PROCEDURE dbo.proc_MergeLanguage
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET LanguageID = @TargetID WHERE LanguageID = @SourceID
	DELETE FROM xLanguage WHERE LanguageID = @SourceID

proc_MergeLawAgency
CREATE PROCEDURE dbo.proc_MergeLawAgency
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Interventions SET LawAgencyID = @TargetID WHERE LawAgencyID = @SourceID
	DELETE FROM xLawEnforcementAgency WHERE AgencyID = @SourceID

proc_MergeLocation
CREATE PROCEDURE dbo.proc_MergeLocation
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET LocationID = @TargetID WHERE LocationID = @SourceID
	UPDATE Calls SET LocationID = @TargetID WHERE LocationID = @SourceID
	DELETE FROM xLocation WHERE LocationID = @SourceID

proc_MergeParticipants
CREATE PROCEDURE dbo.proc_MergeParticipants
	(@FromParticipantID INT, @ToParticipantID INT, @UserName VARCHAR(50))
	AS
	UPDATE EmerContacts SET ParticipantID = @ToParticipantID WHERE ParticipantID = @FromParticipantID
	UPDATE AbuserAlerts SET ParticipantID = @ToParticipantID WHERE ParticipantID = @FromParticipantID
	UPDATE Children SET ParticipantID = @ToParticipantID WHERE ParticipantID = @FromParticipantID
	UPDATE Intakes SET ParticipantID = @ToParticipantID WHERE ParticipantID = @FromParticipantID
	UPDATE LinkedIntakes SET ParticipantID = @ToParticipantID WHERE ParticipantID = @FromParticipantID
	UPDATE Notes SET ClientID = @ToParticipantID WHERE ClientID = @FromParticipantID And ClientTypeID = 1
	UPDATE Referrals SET ClientID = @ToParticipantID WHERE ClientID = @FromParticipantID And ClientTypeID = 1
	UPDATE ClientSessions SET ClientID = @ToParticipantID WHERE ClientID = @FromParticipantID And ClientTypeID = 1
	UPDATE Participants SET DeletedDate = getdate(), DeletedBy = @UserName WHERE ParticipantID = @FromParticipantID

proc_MergePriorResidence
CREATE PROCEDURE dbo.proc_MergePriorResidence
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET PriorResidenceID = @TargetID WHERE PriorResidenceID = @SourceID
	DELETE FROM xPriorResidence WHERE PriorResidenceID = @SourceID

proc_MergeProgram
CREATE PROCEDURE dbo.proc_MergeProgram
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE ProgramServices SET ProgramID = @TargetID 
	WHERE ProgramID = @SourceID AND ServiceID NOT IN
		(SELECT ServiceID FROM ProgramServices WHERE ProgramID = @TargetID)
	DELETE FROM ProgramServices WHERE ProgramID = @SourceID
	UPDATE [Sessions] SET ProgramID = @TargetID WHERE ProgramID = @SourceID
	UPDATE CallServices SET ProgramID = @TargetID WHERE ProgramID = @SourceID
	DELETE FROM Programs WHERE ProgramID = @SourceID

proc_MergeReasonDenied
CREATE PROCEDURE dbo.proc_MergeReasonDenied
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE ShelterRequests SET ReasonDeniedID = @TargetID WHERE ReasonDeniedID = @SourceID
	DELETE FROM xReasonDenied WHERE ReasonDeniedID = @SourceID

proc_MergeReferralSource
CREATE PROCEDURE dbo.proc_MergeReferralSource
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Calls SET ReferralSourceID = @TargetID WHERE ReferralSourceID = @SourceID
	UPDATE Intakes SET ReferralSourceID = @TargetID WHERE ReferralSourceID = @SourceID
	DELETE FROM xReferralSource WHERE ReferralSourceID = @SourceID

proc_MergeReferralType
CREATE PROCEDURE dbo.proc_MergeReferralType
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Referrals SET ReferralTypeID = @TargetID WHERE ReferralTypeID = @SourceID
	DELETE FROM xReferralType WHERE ReferralTypeID = @SourceID

proc_MergeReleaseEntity
CREATE PROCEDURE dbo.proc_MergeReleaseEntity
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE ReleaseEntities
	SET EntityID = @TargetID
	WHERE EntityID = @SourceID AND ReleaseID NOT IN
		(SELECT ReleaseID FROM ReleaseEntities
		WHERE EntityID = @TargetID)
	DELETE FROM ReleaseEntities WHERE EntityID = @SourceID
	DELETE FROM InfoEntities WHERE EntityID = @SourceID

proc_MergeReleaseType
CREATE PROCEDURE dbo.proc_MergeReleaseType
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE InfoReleases SET ReleaseTypeID = @TargetID WHERE ReleaseTypeID = @SourceID
	DELETE FROM ReleaseTypes WHERE ReleaseTypeID = @SourceID

proc_MergeReligion
CREATE PROCEDURE dbo.proc_MergeReligion
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Intakes SET ReligionID = @TargetID WHERE ReligionID = @SourceID
	DELETE FROM xReligion WHERE ReligionID = @SourceID

proc_MergeService
CREATE PROCEDURE dbo.proc_MergeService
	(@SourceID INT, @TargetID INT)
	AS	
	UPDATE ProgramServices SET ServiceID = @TargetID 
	WHERE ServiceID = @SourceID AND ProgramID NOT IN
		(SELECT ProgramID FROM ProgramServices WHERE ServiceID = @TargetID)
	DELETE FROM ProgramServices WHERE ServiceID = @SourceID
	UPDATE ServiceFocus SET ServiceID = @TargetID
	WHERE ServiceID = @SourceID AND FocusID NOT IN
		(SELECT FocusID FROM ServiceFocus WHERE ServiceID = @TargetID)
	DELETE FROM ServiceFocus WHERE ServiceID = @SourceID
	UPDATE ServiceMap SET ServiceID = @TargetID 
	WHERE ServiceID = @SourceID AND GrantorID NOT IN
		(SELECT GrantorID FROM ServiceMap WHERE ServiceID = @TargetID)
	DELETE FROM ServiceMap WHERE ServiceID = @SourceID
	UPDATE [Sessions] SET ServiceID = @TargetID WHERE ServiceID = @SourceID
	DELETE FROM Services WHERE ServiceID = @SourceID

proc_MergeServiceLocation
CREATE PROCEDURE dbo.proc_MergeServiceLocation
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Sessions SET LocationID = @TargetID WHERE LocationID = @SourceID
	DELETE FROM xServiceLocation WHERE LocationID = @SourceID

proc_MergeShelter
CREATE PROCEDURE dbo.proc_MergeShelter
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Beds SET ShelterID = @TargetID WHERE ShelterID = @SourceID
	UPDATE Rooms SET ShelterID = @TargetID WHERE ShelterID = @SourceID
	UPDATE Intakes SET ShelterID = @TargetID WHERE ShelterID = @SourceID
	UPDATE Calls SET ShelterID = @TargetID WHERE ShelterID = @SourceID
	DELETE FROM Shelters WHERE ShelterID = @SourceID

proc_MergeTopic
CREATE PROCEDURE dbo.proc_MergeTopic
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE PresentationTopics SET TopicID = @TargetID 
		WHERE TopicID = @SourceID AND PresentationID NOT IN
		(SELECT PresentationID FROM PresentationTopics WHERE TopicID = @TargetID)
	DELETE FROM xTopic WHERE TopicID = @SourceID

proc_MergeTribe
CREATE PROCEDURE dbo.proc_MergeTribe
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE TribalAffiliation SET TribeID = @TargetID WHERE TribeID = @SourceID
	DELETE FROM xTribe WHERE TribeID = @SourceID

proc_MergeTripPurpose
CREATE PROCEDURE dbo.proc_MergeTripPurpose
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Trips SET PurposeID = @TargetID WHERE PurposeID = @SourceID
	DELETE FROM xTripPurpose WHERE PurposeID = @SourceID

proc_MergeVehicle
CREATE PROCEDURE dbo.proc_MergeVehicle
	(@SourceID INT, @TargetID INT)
	AS
	UPDATE Trips SET VehicleID = @TargetID WHERE VehicleID = @SourceID
	DELETE FROM Vehicles WHERE VehicleID = @SourceID

proc_RebuildIndexes
CREATE PROCEDURE dbo.proc_RebuildIndexes
	(@TableName VARCHAR(100))
	AS
	DECLARE @sql NVARCHAR(500)
	SET @sql = 'ALTER INDEX ALL ON ' + @TableName + ' REBUILD WITH(ONLINE = OFF)'
	EXEC (@sql)

proc_RestoreAbuser
CREATE PROCEDURE dbo.proc_RestoreAbuser
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Abusers SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AbuserID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE AbuserIntakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AbuserID = @ID
	UPDATE Notes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ClientID = @ID AND ClientTypeID = 3
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE ClientID = @ID AND ClientTypeID = 3
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ClientID = @ID AND ClientTypeID = 3
	END

proc_RestoreAbuserAlert
CREATE PROCEDURE dbo.proc_RestoreAbuserAlert
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE AbuserAlerts SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AlertID = @ID

proc_RestoreAbuserIntake
CREATE PROCEDURE dbo.proc_RestoreAbuserIntake
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE AbuserIntakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AbuserIntakeID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE IntakeID = @ID AND ClientTypeID = 3
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID AND ClientTypeID = 3
	END

proc_RestoreAlias
CREATE PROCEDURE dbo.proc_RestoreAlias
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Aliases SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AliasID = @ID

proc_RestoreAssessment
CREATE PROCEDURE dbo.proc_RestoreAssessment
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Assessments SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE AssessmentID = @ID

proc_RestoreCall
CREATE PROCEDURE dbo.proc_RestoreCall
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Calls SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE CallID = @ID

proc_RestoreChild
CREATE PROCEDURE dbo.proc_RestoreChild
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Children SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ChildID = @ID
	IF @RestoreAll = 1 BEGIN
	UPDATE ChildIntakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ChildID = @ID
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE ClientID = @ID AND ClientTypeID = 2
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ClientID = @ID AND ClientTypeID = 2
	UPDATE ChildAliases SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE ChildID = @ID
	END

proc_RestoreChildAlias
CREATE PROCEDURE dbo.proc_RestoreChildAlias
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE ChildAliases SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE AliasID = @ID

proc_RestoreChildIntake
CREATE PROCEDURE dbo.proc_RestoreChildIntake
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE ChildIntakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ChildIntakeID = @ID
	IF @RestoreAll = 1 
	BEGIN
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE IntakeID = @ID AND ClientTypeID = 2
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID AND ClientTypeID = 2
	END

proc_RestoreClientSession
CREATE PROCEDURE dbo.proc_RestoreClientSession
	(@SessionID INT, @ClientID INT, @ClientTypeID INT)
	AS
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' 
	WHERE SessionID = @SessionID AND ClientID = @ClientID AND ClientTypeID = @ClientTypeID
	UPDATE [Sessions] SET DeletedDate = Null, DeletedBy = '' WHERE SessionID = @SessionID

proc_RestoreCommunityMember
CREATE PROCEDURE dbo.proc_RestoreCommunityMember
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE CommunityMembers SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE MemberID = @ID
	IF @RestoreAll = 1
	BEGIN
	DECLARE @GetDate DATETIME
	SET @GetDate = GETDATE()
	UPDATE Notes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 4
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE ClientID = @ID AND ClientTypeID = 4
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 4
	UPDATE Interventions SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 4
	END

proc_RestoreCredential
CREATE PROCEDURE dbo.proc_RestoreCredential
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Credentials SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE CredentialID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE TrainingSessions SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE SubjectID = @ID
	END

proc_RestoreEmergencyContact
CREATE PROCEDURE dbo.proc_RestoreEmergencyContact
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE EmerContacts SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE EmerContactID = @ID

proc_RestoreGrant
CREATE PROCEDURE dbo.proc_RestoreGrant
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Grants SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE GrantID = @ID

proc_RestoreGrantor
CREATE PROCEDURE dbo.proc_RestoreGrantor
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Grantors SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE GrantorID = @ID
	IF @RestoreAll = 1
	BEGIN
		UPDATE Grants SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE GrantorID = @ID
		UPDATE GrantorServices SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE GrantorID = @ID
		UPDATE ServiceMap SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE GrantorID = @ID 
	END

proc_RestoreInfoRelease
CREATE PROCEDURE dbo.proc_RestoreInfoRelease
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE InfoReleases SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE ReleaseID = @ID

proc_RestoreIntake
CREATE PROCEDURE dbo.proc_RestoreIntake
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Intakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE ChildIntakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID
	UPDATE IntakeBeds SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID AND ClientTypeID = 1
	UPDATE IntakeCalls SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE IntakeID = @ID AND ClientTypeID = 1
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE IntakeID = @ID AND ClientTypeID = 1	
	UPDATE Questionnaires SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE IntakeID = @ID AND ClientTypeID = 1
	UPDATE Assessments SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE IntakeID = @ID
	END

proc_RestoreIntakeBedAssignment
CREATE PROCEDURE dbo.proc_RestoreIntakeBedAssignment
	(@IntakeID INT, @ClientTypeID INT, @BedID INT, @DateIn DATETIME, @UserName VARCHAR(50))
	AS
	UPDATE IntakeBeds SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() 
	WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID AND BedID = @BedID AND DateIn = @DateIn

proc_RestoreIntervention
CREATE PROCEDURE dbo.proc_RestoreIntervention
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Interventions SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE() WHERE InterventionID = @ID
	IF @RestoreAll = 1
		BEGIN
			UPDATE Sessions SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = GETDATE()
			WHERE SessionID = (SELECT TOP 1 SessionID FROM Interventions WHERE InterventionID = @ID)
		END

proc_RestoreNote
CREATE PROCEDURE dbo.proc_RestoreNote
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Notes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE NoteID = @ID

proc_RestoreParticipant
CREATE PROCEDURE dbo.proc_RestoreParticipant
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Participants SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ParticipantID = @ID
	IF @RestoreAll = 1
	BEGIN
	DECLARE @GetDate DATETIME
	SET @GetDate = GETDATE()
	UPDATE Children SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ParticipantID = @ID
	UPDATE Intakes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ParticipantID = @ID
	UPDATE ClientSessions SET DeletedDate = Null, DeletedBy = '' WHERE ClientID = @ID AND ClientTypeID = 1
	UPDATE [Sessions] SET DeletedDate = Null, DeletedBy = '' WHERE SessionID IN
		(SELECT SessionID FROM ClientSessions WHERE ClientID = @ID AND ClientTypeID = 1)
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 1
	UPDATE EmerContacts SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ParticipantID = @ID
	UPDATE Aliases SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ParticipantID = @ID
	UPDATE Notes SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 1
	UPDATE AbuserAlerts SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ParticipantID = @ID
	UPDATE Interventions SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate WHERE ClientID = @ID AND ClientTypeID = 1
	END

proc_RestoreParticipantFile
CREATE PROCEDURE dbo.proc_RestoreParticipantFile
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE ParticipantFiles SET DeletedDate = NULL, DeletedBy = '' WHERE FileID = @ID

proc_RestorePresentation
CREATE PROCEDURE dbo.proc_RestorePresentation
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Presentations SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE PresentationID = @ID

proc_RestoreQuestionnaire
CREATE PROCEDURE dbo.proc_RestoreQuestionnaire
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Questionnaires SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE QuestionnaireID = @ID

proc_RestoreReferral
CREATE PROCEDURE dbo.proc_RestoreReferral
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Referrals SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ReferralID = @ID
	UPDATE StaffReferrals SET DeletedDate = Null, DeletedBy = '' WHERE ReferralID = @ID

proc_RestoreReportNarrative
CREATE PROCEDURE dbo.proc_RestoreReportNarrative
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE ReportNarratives SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE NarrativeID = @ID

proc_RestoreServiceSession
CREATE PROCEDURE dbo.proc_RestoreServiceSession
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Sessions SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE SessionID = @ID

proc_RestoreStaffMember
CREATE PROCEDURE dbo.proc_RestoreStaffMember
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Staff SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE StaffID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE StaffSessions SET DeletedDate = Null, DeletedBy = '' WHERE StaffID = @ID
	END

proc_RestoreSurvey
CREATE PROCEDURE dbo.proc_RestoreSurvey
	(@RestoreAll BIT, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE Surveys SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE SurveyID = @ID
	IF @RestoreAll = 1
	BEGIN
	UPDATE Questionnaires SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE SurveyID = @ID
	END

proc_RestoreTrainingSession
CREATE PROCEDURE dbo.proc_RestoreTrainingSession
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE TrainingSessions SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE SessionID = @ID

proc_RestoreVolunteerActivity
CREATE PROCEDURE dbo.proc_RestoreVolunteerActivity
	(@RestoreAll BIT = 1, @ID INT, @UserName VARCHAR(50))
	AS
	UPDATE VolunteerActivities SET DeletedDate = Null, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = getdate() WHERE ActivityID = @ID

proc_SaveAbuserAlert
CREATE PROCEDURE dbo.proc_SaveAbuserAlert
	(@IsNew BIT, @AlertID INT OUTPUT, @ParticipantID INT, @FirstName VARCHAR(50), @LastName VARCHAR(50), @MI CHAR(1),
	 @AbuserRelationshipID INT, @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(50), @Zip VARCHAR(10),
	 @Sex CHAR(1), @Height VARCHAR(10), @Weight VARCHAR(3), @EyeColor VARCHAR(15), @FacialHair VARCHAR(15),
	 @HairColor VARCHAR(15), @HairLength VARCHAR(15), @SkinTone VARCHAR(15), @Marks VARCHAR(500), @EthnicityID INT,
	 @Vehicle VARCHAR(50), @VehicleLicense VARCHAR(15), @VehicleColor VARCHAR(15), @IsArmed BIT, @Image VARBINARY(MAX),
	 @UserName VARCHAR(50), @GetDate SMALLDATETIME OUTPUT)
	 AS
	 SELECT @GetDate = GETDATE()
	 IF @IsNew = 1
		BEGIN
			INSERT INTO AbuserAlerts
				(ParticipantID, FirstName, LastName, MI, AbuserRelationshipID, [Address], City, [State], Zip,
				 Sex, Height, Weight, EyeColor, FacialHair, HairColor, HairLength, SkinTone, Marks, EthnicityID,
				 Vehicle, VehicleLicense, VehicleColor, IsArmed, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
				VALUES
				(@ParticipantID, @FirstName, @LastName, @MI, @AbuserRelationshipID, @Address, @City, @State, @Zip,
				 @Sex, @Height, @Weight, @EyeColor, @FacialHair, @HairColor, @HairLength, @SkinTone, @Marks, @EthnicityID,
				 @Vehicle, @VehicleLicense, @VehicleColor, @IsArmed, @GetDate, @UserName, @GetDate, @UserName)
			SELECT @AlertID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE AbuserAlerts
			SET
				ParticipantID = @ParticipantID, FirstName = @FirstName, LastName = @LastName, 
				MI = @MI, AbuserRelationshipID = @AbuserRelationshipID, Address = @Address, City = @City, 
				State = @State, Zip = @Zip, Sex = @Sex, Height = @Height, Weight = @Weight, EyeColor = @EyeColor, 
				FacialHair = @FacialHair, HairColor = @HairColor, HairLength = @HairLength, SkinTone = @SkinTone, 
				Marks = @Marks, EthnicityID = @EthnicityID, Vehicle = @Vehicle, VehicleLicense = @VehicleLicense, 
				VehicleColor = @VehicleColor, IsArmed = @IsArmed, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE AlertID = @AlertID
			DELETE FROM AbuserAlertImages WHERE AlertID = @AlertID
		END
	IF @Image IS NOT NULL
		BEGIN
			INSERT INTO AbuserAlertImages (AlertID, Image) VALUES (@AlertID, @Image)
		END

proc_SaveAbuserIntake
CREATE PROCEDURE dbo.proc_SaveAbuserIntake
	(@AbuserIntakeID INT OUTPUT, @AbuserID INT, @ProgramID INT, @SubstanceAbuseID INT, @SubstanceTreatmentID INT,
	@CounselingStatusID INT, @CounselingResultID INT, @EntryDate SMALLDATETIME, @ExitDate SMALLDATETIME, @VictimRelationshipID INT,
	@TANF BIT, @WIC BIT, @SSI BIT, @SSDI BIT, @FoodStamps BIT, @LowIncomeHousing BIT, @AHCCCS BIT, @CashAssistance BIT,
	@Income INT, @AbusePhysical BIT, @AbuseSexual BIT, @AbuseVerbalPsychological BIT, @AbuseEconomic BIT,
	@AbusedAsChild BIT, @AbuseWitness BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @AbuserIntakeID = 0
		BEGIN
			INSERT INTO AbuserIntakes
			(AbuserID, ProgramID, SubstanceAbuseID, SubstanceTreatmentID, CounselingStatusID, CounselingResultID,
			EntryDate, ExitDate, TANF, WIC, SSI, SSDI, FoodStamps, LowIncomeHousing, AHCCCS, CashAssistance,
			Income, AbusePhysical, AbuseSexual, AbuseVerbalPsychological, AbuseEconomic, AbusedAsChild, AbuseWitness, 
			VictimRelationshipID, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
			Values
			(@AbuserID, @ProgramID, @SubstanceAbuseID, @SubstanceTreatmentID, @CounselingStatusID, @CounselingResultID,
			@EntryDate, @ExitDate, @TANF, @WIC, @SSI, @SSDI, @FoodStamps, @LowIncomeHousing, @AHCCCS, @CashAssistance,
			@Income, @AbusePhysical, @AbuseSexual, @AbuseVerbalPsychological, @AbuseEconomic,
			@AbusedAsChild, @AbuseWitness, @VictimRelationshipID, @UserName, @UserName, @GetDate, @GetDate)
			SELECT @AbuserIntakeID = SCOPE_IDENTITY()		
		END
	ELSE
		BEGIN
			UPDATE AbuserIntakes
			Set AbuserID = @AbuserID, ProgramID = @ProgramID, SubstanceAbuseID = @SubstanceAbuseID, 
			SubstanceTreatmentID = @SubstanceTreatmentID, CounselingStatusID = @CounselingStatusID, 
			CounselingResultID = @CounselingResultID, EntryDate = @EntryDate, ExitDate = @ExitDate, TANF = @TANF,
			WIC = @WIC, SSI = @SSI, SSDI = @SSDI, FoodStamps = @FoodStamps, LowIncomeHousing = @LowIncomeHousing, 
			AHCCCS = @AHCCCS, CashAssistance = @CashAssistance,	Income = @Income, AbusePhysical = @AbusePhysical, 
			AbuseSexual = @AbuseSexual, AbuseVerbalPsychological = @AbuseVerbalPsychological, AbuseEconomic = @AbuseEconomic,
			AbusedAsChild = @AbusedAsChild, AbuseWitness = @AbuseWitness, ModifiedBy = @UserName, ModifiedDate = @GetDate,
			VictimRelationshipID = @VictimRelationshipID
			WHERE AbuserIntakeID = @AbuserIntakeID		
		END

proc_SaveAssessment
CREATE PROCEDURE dbo.proc_SaveAssessment
	(@AssessmentID INT OUTPUT, @UserName VARCHAR(50), @IntakeID INT,
	@AssessmentDate SMALLDATETIME, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @AssessmentID = 0 -- New Assessment
		BEGIN
			INSERT INTO Assessments (IntakeID, AssessmentDate, CreatedBy, 
				CreatedDate, ModifiedBy, ModifiedDate)
			VALUES (@IntakeID, @AssessmentDate, @UserName, @GetDate,
				@UserName, @GetDate)
			SELECT @AssessmentID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			DELETE FROM AssessmentItems WHERE AssessmentID = @AssessmentID
			UPDATE Assessments
			SET IntakeID = @IntakeID, AssessmentDate = @AssessmentDate,
				ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE AssessmentID = @AssessmentID
		END

proc_SaveAssessmentItem
CREATE PROCEDURE dbo.proc_SaveAssessmentItem
	(@AssessmentID INT , @DomainID INT, @StatusID INT)
	AS
	INSERT INTO AssessmentItems (AssessmentID, DomainID, StatusID)
	VALUES (@AssessmentID, @DomainID, @StatusID)

proc_SaveBackupSettings
CREATE PROCEDURE dbo.proc_SaveBackupSettings
	(@BackupAutomatic BIT, @BackupFrequency INT, @BackupPath VARCHAR(500), @TempPath VARCHAR(500), @BackupOnServer BIT)
	AS
	UPDATE zsSettings
	SET BackupAutomatic = @BackupAutomatic, BackupFrequency = @BackupFrequency, BackupPath = @BackupPath, TempPath = @TempPath, BackupOnServer = @BackupOnServer

proc_SaveCall
-- Modify the procedure for saving hotline calls to accomodate the ContactType column
CREATE PROCEDURE proc_SaveCall
	(@IsNew BIT, @ContactType INT, @ShelterID INT, @CallTypeID INT, @CallSubjectID INT, @ReferralSourceID INT, @LocationID INT, 
	@CallDate SMALLDATETIME, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50), @NumberChildren INT, @Note VARCHAR(500), 
	@Initials VARCHAR(25), @UserName VARCHAR(50), @ShelterRequested BIT, @RequestOutcomeID INT, @ReasonDeniedID INT, 
	@Sex CHAR(1), @Anonymous BIT, @GetDate SMALLDATETIME OUTPUT, @TurnAway BIT, @CallID INT OUTPUT) 
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Calls 
			(ContactType, ShelterID, CallTypeID, CallSubjectID, ReferralSourceID, LocationID, CallDate, FirstName, LastName, MI, NumberChildren, 
			Note, Initials, Sex, [Anonymous], TurnAway, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy) 
			Values 
			(@ContactType, @ShelterID, @CallTypeID, @CallSubjectID, @ReferralSourceID, @LocationID, @CallDate, @FirstName, @LastName, @MI, @NumberChildren, 
			@Note, @Initials, @Sex, @Anonymous, @TurnAway, @GetDate, @UserName, @GetDate, @UserName) 
			SELECT @CallID = SCOPE_IDENTITY() 
			IF @ShelterRequested > 0 
				INSERT INTO ShelterRequests 
					(CallID, RequestOutcomeID, ReasonDeniedID) 
					Values 
					(@CallID, @RequestOutcomeID, @ReasonDeniedID)		
		END
	ELSE
		BEGIN
			UPDATE Calls 
			SET ContactType = @ContactType, ShelterID = @ShelterID, CallTypeID = @CallTypeID, CallSubjectID = @CallSubjectID, ReferralSourceID = @ReferralSourceID, LocationID = @LocationID, 
			CallDate = @CallDate, FirstName = @FirstName, MI = @MI, LastName = @LastName, NumberChildren = @NumberChildren, Note = @Note, Initials = @Initials, 
			Sex = @Sex, [Anonymous] = @Anonymous, TurnAway = @TurnAway, ModifiedBy = @UserName, ModifiedDate = @GetDate   
			WHERE CallID = @CallID 
			DELETE FROM HotlineReferrals WHERE CallID = @CallID 
			DELETE FROM ShelterRequests WHERE CallID = @CallID
			DELETE FROM StaffCallService WHERE SessionID IN
				(SELECT SessionID FROM CallServices WHERE CallID = @CallID)
			DELETE FROM CallServices WHERE CallID = @CallID 
			IF @ShelterRequested > 0 
				INSERT INTO ShelterRequests 
					(CallID, RequestOutcomeID, ReasonDeniedID) 
				Values 
				(@CallID, @RequestOutcomeID, @ReasonDeniedID)		
		END

proc_SaveChildIntake
CREATE PROCEDURE dbo.proc_SaveChildIntake
	(@IsNew BIT, @IntakeID INT, @ChildID INT, @EntryDate SMALLDATETIME, @ExitDate SMALLDATETIME, 
	@TanfEligible BIT, @SSI BIT, @SSDI BIT, @TANF BIT, @WIC BIT, @AHCCCS BIT, @LowIncomeHousing BIT, @KidsCare BIT, @FoodStamps BIT, 
	@AbusePhysical BIT, @AbuseSexual BIT, @AbuseVerbalPsychological BIT, @AbuseEconomic BIT, @AbuseWitness BIT,
	@MentalIllness BIT, @PhysDisability BIT, @DevDisability BIT, @ChronicHealthCondition BIT, @HIVAIDS BIT, @SubstanceAbuseID INT,  
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @ChildIntakeID INT OUTPUT, @HealthPlanGoal BIT = 0, @HealthImproved BIT = 0) 	
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			DELETE FROM ChildIntakes  
			WHERE IntakeID = @IntakeID AND ChildID = @ChildID 
			INSERT INTO ChildIntakes 
				(IntakeID, ChildID, EntryDate, ExitDate, TanfEligible, SSI, SSDI, TANF, WIC, AHCCCS, LowIncomeHousing, KidsCare, FoodStamps, 
				AbusePhysical, AbuseSexual, AbuseVerbalPsychological, AbuseEconomic, AbuseWitness, 
				MentalIllness, PhysDisability, DevDisability, ChronicHealthCondition, HIVAIDS, SubstanceAbuseID,
				HealthPlanGoal, HealthImproved, CreatedDate, CreatedBy, ModifiedBy) 
			Values 
				(@IntakeID, @ChildID, @EntryDate, @ExitDate, @TanfEligible, @SSI, @SSDI, @TANF, @WIC, @AHCCCS, @LowIncomeHousing, @KidsCare, @FoodStamps, 
				@AbusePhysical, @AbuseSexual, @AbuseVerbalPsychological, @AbuseEconomic, @AbuseWitness, 
				@MentalIllness, @PhysDisability, @DevDisability, @ChronicHealthCondition, @HIVAIDS, @SubstanceAbuseID,
				@HealthPlanGoal, @HealthImproved, @GetDate, @UserName, @UserName) 
			SELECT @ChildIntakeID = SCOPE_IDENTITY()		
		END
	ELSE
		BEGIN
			UPDATE ChildIntakes 
			Set EntryDate = @EntryDate, ExitDate = @ExitDate, TanfEligible = @TanfEligible, SSI = @SSI, SSDI = @SSDI, TANF = @TANF, WIC = @WIC, 
			AHCCCS = @AHCCCS, LowIncomeHousing = @LowIncomeHousing, KidsCare = @KidsCare, FoodStamps = @FoodStamps, 
			AbusePhysical = @AbusePhysical, AbuseSexual = @AbuseSexual, AbuseVerbalPsychological = @AbuseVerbalPsychological, 
			AbuseEconomic = @AbuseEconomic, AbuseWitness = @AbuseWitness, 
			MentalIllness = @MentalIllness, PhysDisability = @PhysDisability, DevDisability = @DevDisability,
			ChronicHealthCondition = @ChronicHealthCondition, HIVAIDS = @HIVAIDS, SubstanceAbuseID = @SubstanceAbuseID,
			HealthPlanGoal = @HealthPlanGoal, HealthImproved = @HealthImproved,
			ModifiedBy = @UserName, ModifiedDate = getdate(), DeletedDate = Null, DeletedBy = '' 
			WHERE IntakeID = @IntakeID And ChildID = @ChildID 
			DELETE FROM ChildAbsences WHERE ChildIntakeID = @ChildIntakeID
			IF @ExitDate IS NOT NULL
				BEGIN
					UPDATE IntakeBeds 
					SET DateOut = @ExitDate, ModifiedBy = @UserName, ModifiedDate = @GetDate
					WHERE IntakeID = @ChildIntakeID AND ClientTypeID = 2 AND DateOut IS NULL
				END
		END

proc_SaveCommunityMember
-- Modify the procedure to save a community member to include IsYouth
CREATE PROCEDURE proc_SaveCommunityMember
	(@IsNew BIT, @IsCurrent BIT, @MemberID INT OUTPUT, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50),
	@Sex CHAR(1), @DOB SMALLDATETIME, @EthnicityID INT, @VictimTypeID INT, @OptionalIdentifier VARCHAR(50),
	@TribeID INT, @IsYouth BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT) 
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO CommunityMembers
				(IsCurrent, FirstName, MI, LastName, Sex, DOB, EthnicityID, VictimTypeID, OptionalIdentifier, 
				IsYouth, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
				VALUES
				(@IsCurrent, @FirstName, @MI, @LastName, @Sex, @DOB, @EthnicityID, @VictimTypeID, @OptionalIdentifier, 
				@IsYouth, @UserName, @GetDate, @UserName, @GetDate)
			SELECT @MemberID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE CommunityMembers
			SET IsCurrent = @IsCurrent, FirstName = @FirstName, MI = @MI, LastName = @LastName, Sex = @Sex,
				DOB = @DOB, EthnicityID = @EthnicityID, VictimTypeID = @VictimTypeID, OptionalIdentifier = @OptionalIdentifier,
				IsYouth = @IsYouth,  ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE MemberID = @MemberID
			DELETE FROM TribalAffiliation WHERE ClientID = @MemberID And ClientTypeID = 4
		END	
	IF @EthnicityID IN (7, 8) AND @TribeID > 0
		BEGIN
			INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@MemberID, 4, @TribeID)
		END

proc_SaveEntry
CREATE PROCEDURE proc_SaveEntry
	(@Entry VARCHAR(100), @RecordID INT OUTPUT, @RecordType VARCHAR(100), 
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @RecordType = 'ReleaseType'
		BEGIN
			IF @RecordID = 0 -- New Record
				BEGIN
					INSERT INTO ReleaseTypes (ReleaseType, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
						VALUES (@Entry, @UserName, @GetDate, @UserName, @GetDate)
					SELECT @RecordID = SCOPE_IDENTITY()
				END
			ELSE  
				BEGIN
					UPDATE ReleaseTypes 
					SET ReleaseType = @Entry, ModifiedBy = @UserName, ModifiedDate = @GetDate
					WHERE ReleaseTypeID = @RecordID
				END
		END
	IF @RecordType = 'InfoEntity'
		BEGIN
			IF @RecordID = 0
				BEGIN
					INSERT INTO InfoEntities (Entity, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
						VALUES (@Entry, @UserName, @GetDate, @UserName, @GetDate)
					SELECT @RecordID = SCOPE_IDENTITY()
				END
			ELSE
				BEGIN
					UPDATE InfoEntities
					SET Entity = @Entry, ModifiedBy = @UserName, ModifiedDate = @GetDate
					WHERE EntityID = @RecordID
				END
		END
	IF @RecordType = 'LawAgency'
		BEGIN
			IF @RecordID = 0
				BEGIN
					INSERT INTO xLawEnforcementAgency (Agency, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
						VALUES (@Entry, @UserName, @GetDate, @UserName, @GetDate)
					SELECT @RecordID = SCOPE_IDENTITY()
				END
			ELSE
				BEGIN
					UPDATE xLawEnforcementAgency
					SET Agency = @Entry, ModifiedBy = @UserName, ModifiedDate = @GetDate
					WHERE AgencyID = @RecordID
				END
		END

proc_SaveGrantor
-- Fix the Save Grantor procedure to get MaxID from Grantors, not GrantorServices
CREATE PROCEDURE dbo.proc_SaveGrantor
	(@Grantor VARCHAR(50), @UserName VARCHAR(50), @IsNew BIT, @GetDate DATETIME OUTPUT, @GrantorID INT OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			DECLARE @MaxID INT
			SET @MaxID = (SELECT MAX(GrantorID) FROM Grantors)
			IF @MaxID < 101 SET @MaxID = 101 ELSE SET @MaxID = @MaxID + 1
			INSERT INTO Grantors (GrantorID, Grantor, CreatedBy, ModifiedBy, CreatedDate)
			Values
			(@MaxID, @Grantor, @UserName, @UserName, @GetDate)
			SELECT @GrantorID = @MaxID
		END
	ELSE
		BEGIN
			UPDATE Grantors
			SET Grantor = @Grantor, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE GrantorID = @GrantorID
			UPDATE GrantorServices
			SET DeletedDate = @GetDate, DeletedBy = @UserName
			WHERE GrantorID = @GrantorID
		END

proc_SaveGrantorService
CREATE PROCEDURE dbo.proc_SaveGrantorService
	(@GrantorID INT, @GrantorServiceID INT OUTPUT, @GrantorService VARCHAR(50), @IsCurrent BIT, 
	@UserName VARCHAR(50), @GetDate DATETIME, @IsDeleted BIT)
	AS
	IF @GrantorServiceID  < 1 -- New GrantorService
		-- See if "new" service matches one that's been deleted
		BEGIN
			IF (SELECT TOP 1 GrantorServiceID FROM GrantorServices WHERE GrantorService = @GrantorService
				AND GrantorID = @GrantorID AND DeletedDate IS NOT NULL) IS NULL
				BEGIN
					-- No matching 'Deleted' service; insert the new service at the available ID value
					SELECT @GrantorServiceID = MAX(GrantorServiceID) FROM GrantorServices WHERE GrantorID = @GrantorID
					BEGIN
						IF @GrantorServiceID IS NULL 
							SELECT @GrantorServiceID = @GrantorID * 100 + 1
						ELSE
							SELECT @GrantorServiceID = @GrantorServiceID + 1
					END
					INSERT INTO GrantorServices
					(GrantorServiceID, GrantorID, GrantorService, IsCurrent, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
					Values
					(@GrantorServiceID, @GrantorID, @GrantorService, @IsCurrent, @UserName, @UserName, @GetDate, @GetDate)
				END
			ELSE
				-- Matching 'deleted' service exists; just undelete it
				BEGIN
					UPDATE GrantorServices
					SET DeletedDate = NULL, DeletedBy = '', ModifiedBy = @UserName, ModifiedDate = @GetDate
					WHERE GrantorService = @GrantorService AND GrantorID = @GrantorID
					SELECT @GrantorServiceID = (SELECT TOP 1 GrantorServiceID FROM GrantorServices
					WHERE GrantorService = @GrantorService AND GrantorID = @GrantorID)
				END
		END
	ELSE -- Update of existing service; only name, current and deleted status modified by user.
		DECLARE @DeletedDate SMALLDATETIME, @DeletedBy VARCHAR(50)
		IF @IsDeleted = 1
			BEGIN
				SET @DeletedDate = @GetDate
				SET @DeletedBy = @UserName
			END
		ELSE
			BEGIN
				SET @DeletedDate = NULL
				SET @DeletedBy = ''
			END
		UPDATE GrantorServices
		SET GrantorService = @GrantorService, IsCurrent = @IsCurrent, ModifiedBy = @UserName, 
			ModifiedDate = @GetDate, DeletedBy = @DeletedBy, DeletedDate = @DeletedDate
		WHERE GrantorServiceID = @GrantorServiceID

proc_SaveInfoRelease
CREATE PROCEDURE dbo.proc_SaveInfoRelease
	(@ReleaseID INT OUTPUT, @UserName VARCHAR(50), @ParticipantID INT,
	@ReleaseTypeID INT, @FromDate SMALLDATETIME, @ToDate SMALLDATETIME, 
	@GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @ReleaseID = 0 -- New Release
		BEGIN
			INSERT INTO InfoReleases (ParticipantID, ReleaseTypeID, FromDate, ToDate,
			CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
			VALUES (@ParticipantID, @ReleaseTypeID, @FromDate, @ToDate,
			@UserName, @GetDate, @UserName, @GetDate)
			SELECT @ReleaseID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			DELETE FROM ReleaseEntities WHERE ReleaseID = @ReleaseID
			UPDATE InfoReleases
			SET ParticipantID = @ParticipantID, ReleaseTypeID = @ReleaseTypeID,
				FromDate = @FromDate, ToDate = @ToDate, ModifiedBy = @UserName,
				ModifiedDate = @GetDate
			WHERE ReleaseID = @ReleaseID
		END

proc_SaveIntakePhase
CREATE PROCEDURE dbo.proc_SaveIntakePhase
	(@IsNew BIT, @PhaseID INT, @IntakeID INT, @BeginDate SMALLDATETIME, @ProjectedEnd SMALLDATETIME,  @CompletedDate SMALLDATETIME)
	AS
	IF @IsNew = 1
		BEGIN
			INSERT INTO IntakePhase
				(IntakeID, PhaseID, BeginDate, ProjectedEnd, CompletedDate)
				VALUES
				(@IntakeID, @PhaseID, @BeginDate, @ProjectedEnd, @CompletedDate)
		END
	ELSE
		BEGIN
			UPDATE IntakePhase
			SET BeginDate = @BeginDate, ProjectedEnd = @ProjectedEnd, CompletedDate = @CompletedDate
			WHERE PhaseID = @PhaseID AND IntakeID = @IntakeID
		END

proc_SaveIntakeTask
CREATE PROCEDURE dbo.proc_SaveIntakeTask
	(@IsNew BIT, @TaskID INT, @IntakeID INT, @CompletedDate SMALLDATETIME)
	AS
	IF @IsNew = 1
		BEGIN
			INSERT INTO IntakeTasks (TaskID, IntakeID, CompletedDate)
				VALUES (@TaskID, @IntakeID, @CompletedDate)
		END
	ELSE
		BEGIN
			UPDATE IntakeTasks
			SET CompletedDate = @CompletedDate
			WHERE TaskID = @TaskID AND IntakeID = @IntakeID
		END

proc_SaveIntervention
CREATE PROCEDURE dbo.proc_SaveIntervention
	(@IsNew BIT, @InterventionID INT OUTPUT, @UserName VARCHAR(50), @ClientID INT, @ClientTypeID INT, @IntakeID INT, 
	@PoliceReport BIT, @PreviousReport BIT, @DVArrestClient BIT, @DVArrestBatterer BIT, @PreviousArrestClient BIT, @PreviousArrestBatterer BIT, 
	@CurrentProtectionOrder BIT, @PreviousProtectionOrder BIT, @EmergencyMedClient BIT, @EmergencyMedBatterer BIT, @LawAgencyID INT, 
	@Abuser VARCHAR(100), @AbuserRelationshipID INT, @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(15), @Zip VARCHAR(15), 
	@Phone VARCHAR(50), @CountyID INT, @LocationID INT, @ReservationID INT, @Advocacy VARCHAR(3000), @GetDate DATETIME OUTPUT,
	@SessionID INT OUTPUT, @ProgramID INT, @ServiceID INT, @SessionDate SMALLDATETIME, @SessionHours FLOAT, @NumberStaff INT)
	AS
	SELECT @GetDate = GETDATE() 
	IF @IsNew = 1
		BEGIN
			INSERT INTO Sessions
				(ProgramID, ServiceID, SessionDate, SessionHours, NumberStaff, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
				VALUES
				(@ProgramID, @ServiceID, @SessionDate, @SessionHours, @NumberStaff, @UserName, @GetDate, @UserName, @GetDate)
			SELECT @SessionID = SCOPE_IDENTITY()			
			INSERT INTO Interventions
				(ClientID, ClientTypeID, SessionID, IntakeID, PoliceReport, PreviousReport, DVArrestClient, DVArrestBatterer, 
				PreviousArrestClient, PreviousArrestBatterer, CurrentProtectionOrder, PreviousProtectionOrder, EmergencyMedClient, 
				EmergencyMedBatterer, LawAgencyID, Abuser, AbuserRelationshipID, Address, City, State, Zip, Phone, CountyID, LocationID, ReservationID,
				Advocacy, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
				VALUES
				(@ClientID, @ClientTypeID, @SessionID, @IntakeID, @PoliceReport, @PreviousReport, @DVArrestClient, @DVArrestBatterer, @PreviousArrestClient,
				@PreviousArrestBatterer, @CurrentProtectionOrder, @PreviousProtectionOrder, @EmergencyMedClient, @EmergencyMedBatterer,
				@LawAgencyID, @Abuser, @AbuserRelationshipID, @Address, @City, @State, @Zip,@Phone, @CountyID, @LocationID, @ReservationID,
				@Advocacy, @UserName, @GetDate, @UserName, @GetDate)
			SELECT @InterventionID = SCOPE_IDENTITY()
			IF @IntakeID > 0
				BEGIN
					UPDATE Intakes
					SET PoliceReport = @PoliceReport, PreviousReport = @PreviousReport, DVArrestClient = @DVArrestClient,
						DVArrestBatterer = @DVArrestBatterer, PreviousArrestClient = @PreviousArrestClient, PreviousArrestBatterer = @PreviousArrestBatterer,
						CurrentProtectionOrder = @CurrentProtectionOrder, PreviousProtectionOrder = @PreviousProtectionOrder,
						EmergencyMedClient = @EmergencyMedClient, EmergencyMedBatterer = @EmergencyMedBatterer, AbuserRelationshipID = @AbuserRelationshipID,
						Address = @Address, City = @City, State = @State, Zip = @Zip, Phone = @Phone, CountyID = @CountyID, LocationID = @LocationID,
						ReservationID = @ReservationID
					WHERE IntakeID = @IntakeID
				END
			INSERT INTO ClientSessions
				(ClientID, ClientTypeID, IntakeID, SessionID)
				VALUES
				(@ClientID, @ClientTypeID, @IntakeID, @SessionID)
		END
	ELSE
		BEGIN
			UPDATE Interventions
			SET ClientID = @ClientID, ClientTypeID = @ClientTypeID, SessionID = @SessionID, IntakeID = @IntakeID, PoliceReport = @PoliceReport,
				PreviousReport = @PreviousReport, DVArrestClient = @DVArrestClient, DVArrestBatterer = @DVArrestBatterer, PreviousArrestClient = @PreviousArrestClient,
				PreviousArrestBatterer = @PreviousArrestBatterer, CurrentProtectionOrder = @CurrentProtectionOrder, PreviousProtectionOrder = @PreviousProtectionOrder,
				EmergencyMedClient = @EmergencyMedClient, EmergencyMedBatterer = @EmergencyMedBatterer, LawAgencyID = @LawAgencyID, Abuser = @Abuser,
				AbuserRelationshipID = @AbuserRelationshipID, Address = @Address, City = @City, State = @State, Zip = @Zip, Phone = @Phone,
				CountyID = @CountyID, LocationID = @LocationID, ReservationID = @ReservationID, Advocacy = @Advocacy,
				ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE InterventionID = @InterventionID
			UPDATE Sessions
			SET ProgramID = @ProgramID, ServiceID = @ServiceID, SessionDate = @SessionDate, SessionHours = @SessionHours,
				NumberStaff = @NumberStaff, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE SessionID = @SessionID
			DELETE FROM StaffSessions WHERE SessionID = @SessionID
			UPDATE ClientSessions
			SET ClientID = @ClientID, ClientTypeID = @ClientTypeID, IntakeID = @IntakeID
			WHERE SessionID = @SessionID
		END

proc_SaveNewChildIntake
CREATE PROCEDURE dbo.proc_SaveNewChildIntake
	(@ChildID INT, @IntakeID INT, @EntryDate SMALLDATETIME, @UserName VARCHAR(50), @ChildIntakeID INT OUTPUT)
	AS
	INSERT INTO ChildIntakes (ChildID, IntakeID, EntryDate, CreatedBy, CreatedDate, ModifiedBy)
		Values (@ChildID, @IntakeID, @EntryDate, @UserName, GETDATE(), @UserName)
	SELECT @ChildIntakeID = SCOPE_IDENTITY()

proc_SaveNewIntake
CREATE PROCEDURE dbo.proc_SaveNewIntake
	(@ShelterID INT, @IntakeTypeID INT, @EntryDate SMALLDATETIME, @ParticipantID INT, 
	@IntakeID INT OUTPUT, @GetDate DATETIME OUTPUT, @UserName VARCHAR(50))
	AS
	SELECT @GetDate = GETDATE()
	IF @IntakeID = 0
		BEGIN
		INSERT INTO Intakes (ShelterID, IntakeTypeID, EntryDate, ParticipantID, CreatedBy, 
			CreatedDate, ModifiedBy, ModifiedDate)
			Values
			(@ShelterID, @IntakeTypeID, @EntryDate, @ParticipantID, @UserName, 
			@GetDate, @UserName, @GetDate)
		SELECT @IntakeID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
		UPDATE Intakes
		SET ShelterID = @ShelterID, IntakeTypeID = @IntakeTypeID, EntryDate = @EntryDate, 
			ModifiedBy = @UserName, ModifiedDate = @GetDate
		WHERE IntakeID = @IntakeID
		DELETE FROM IntakeBeds WHERE ClientTypeID = 1 AND IntakeID = @IntakeID
		DELETE FROM IntakeBeds WHERE ClientTypeID = 2 AND IntakeID IN
			(SELECT ChildIntakeID FROM ChildIntakes WHERE IntakeID = @IntakeID)
		DELETE FROM ChildIntakes WHERE IntakeID = @IntakeID
		END

proc_SaveOrganizationData
CREATE PROCEDURE dbo.proc_SaveOrganizationData
	(@Organization VARCHAR(100), @Address1 VARCHAR(100), @Address2 VARCHAR(100), @City VARCHAR(100), 
	 @State VARCHAR(100), @Zip VARCHAR(100), @Phone VARCHAR(100), @Fax VARCHAR(100), @County VARCHAR(100), 
	 @Director VARCHAR(100), @Email VARCHAR(100)) 
	AS
	UPDATE zShelterData Set ItemValue = @Organization WHERE Item = 'Organization'
	UPDATE zShelterData Set ItemValue = @Address1 WHERE Item = 'Address1'
	UPDATE zShelterData Set ItemValue = @Address2 WHERE Item = 'Address2'
	UPDATE zShelterData Set ItemValue = @City WHERE Item = 'City'
	UPDATE zShelterData Set ItemValue = @State WHERE Item = 'State'
	UPDATE zShelterData Set ItemValue = @Zip WHERE Item = 'Zip'
	UPDATE zShelterData Set ItemValue = @Phone WHERE Item = 'Phone'
	UPDATE zShelterData Set ItemValue = @Fax WHERE Item = 'Fax'
	UPDATE zShelterData Set ItemValue = @County WHERE Item = 'County'
	UPDATE zShelterData Set ItemValue = @Director WHERE Item = 'Director'
	UPDATE zShelterData Set ItemValue = @Email WHERE Item = 'Email'
	RETURN

proc_SaveParticipant
CREATE PROCEDURE proc_SaveParticipant
	(@FirstName VARCHAR(50),@LastName VARCHAR(50),@MI CHAR(1),@OptionalIdentifier VARCHAR(50), @Sex CHAR(1), @DOB SMALLDATETIME, @Veteran BIT, @ChronicallyHomeless BIT, 
	@LGBT BIT, @ReturnStatusID INT, @ReturnIssue VARCHAR(250), @SSN VARCHAR(11), @EthnicityID INT, @TribeID INT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, 
	@ParticipantID INT OUTPUT, @IsNew BIT)
	AS
	SELECT @GetDate = getdate() 
	IF @IsNew = 1
		BEGIN
			INSERT INTO Participants  
			(EthnicityID, FirstName, LastName, MI, OptionalIdentifier, Sex, DOB, Veteran, ChronicallyHomeless, LGBT, SSN, ReturnStatusID, CreatedDate, CreatedBy,ModifiedDate, ModifiedBy)  
			Values  
			(@EthnicityID, @FirstName, @LastName, @MI, @OptionalIdentifier, @Sex, @DOB, @Veteran, @ChronicallyHomeless, @LGBT, @SSN, @ReturnStatusID, GetDate(), @UserName, GetDate(), @UserName)  
			SELECT @ParticipantID = SCOPE_IDENTITY()
			IF @EthnicityID IN (7, 8) AND @TribeID > 0
				INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@ParticipantID, 1, @TribeID)
			IF @ReturnStatusID > 1 AND LEN(@ReturnIssue) > 0
				INSERT INTO ParticipantReturnIssue (ParticipantID, ReturnIssue) Values (@ParticipantID, @ReturnIssue)
			ELSE IF @ReturnStatusID = 1
				DELETE FROM ParticipantReturnIssue WHERE ParticipantID = @ParticipantID
		END
	ELSE
		BEGIN
			UPDATE Participants  
			Set EthnicityID = @EthnicityID, FirstName = @FirstName, LastName = @LastName, MI = @MI, OptionalIdentifier = @OptionalIdentifier, Sex = @Sex, DOB = @DOB,  
			Veteran = @Veteran, ChronicallyHomeless = @ChronicallyHomeless, LGBT = @LGBT, ReturnStatusID = @ReturnStatusID, SSN = @SSN, ModifiedDate = GetDate(), ModifiedBy = @UserName 
			WHERE ParticipantID = @ParticipantID
			DELETE FROM RHBA WHERE ParticipantID = @ParticipantID
			DELETE FROM ParticipantReturnIssue WHERE ParticipantID = @ParticipantID
			DELETE FROM TribalAffiliation WHERE ClientID = @ParticipantID And ClientTypeID = 1
			IF @EthnicityID IN (7, 8) AND @TribeID > 0
				INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@ParticipantID, 1, @TribeID)
			IF @ReturnStatusID > 1 AND LEN(@ReturnIssue) > 0
				INSERT INTO ParticipantReturnIssue (ParticipantID, ReturnIssue) Values (@ParticipantID, @ReturnIssue)
		END

proc_SavePhase
CREATE PROCEDURE dbo.proc_SavePhase
	(@IsNew BIT, @PhaseID INT OUTPUT, @PhaseName VARCHAR(50), @Sequence INT, @IntakeTypeID INT, 
	@ProjectedLength INT, @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Phases
				(PhaseName, Sequence, IntakeTypeID, ProjectedLength, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
				Values
				(@PhaseName, @Sequence, @IntakeTypeID, @ProjectedLength, @IsCurrent, @UserName, @GetDate, @UserName, @GetDate)
			SELECT @PhaseID = SCOPE_IDENTITY()		
		END
	ELSE
		BEGIN
			UPDATE Phases 
				Set PhaseName = @PhaseName, Sequence = @Sequence, IntakeTypeID = @IntakeTypeID, 
					ProjectedLength = @ProjectedLength, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE PhaseID = @PhaseID
		END

proc_SavePresentation
CREATE PROCEDURE dbo.proc_SavePresentation
	(@IsNew BIT, @PresentationID INT OUTPUT, @PresentationDate SMALLDATETIME, @PresentationHours FLOAT = NULL,
	 @PrepHours FLOAT = NULL, @NumberAttended INT, @Location VARCHAR(50), @YouthTargeted BIT,
	 @Note VARCHAR(500), @IsPresentation BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE();
	IF @IsNew = 1
		BEGIN	
			INSERT INTO Presentations
				(PresentationDate, PresentationHours, PrepHours, NumberAttended, Location, YouthTargeted,
				 Note, IsPresentation, CreatedBy, ModifiedBy, CreatedDate)
				Values
				(@PresentationDate, @PresentationHours, @PrepHours, @NumberAttended, @Location, @YouthTargeted,
				 @Note, @IsPresentation, @UserName, @UserName, @GetDate)
			SELECT @PresentationID = SCOPE_IDENTITY()		
		END
	ELSE
		BEGIN
			DELETE FROM StaffPresentations WHERE PresentationID = @PresentationID
			DELETE FROM PresentationTopics WHERE PresentationID = @PresentationID
			UPDATE Presentations
				Set PresentationDate = @PresentationDate, PresentationHours = @PresentationHours, PrepHours = @PrepHours, 
					NumberAttended = @NumberAttended, Location = @Location, YouthTargeted = @YouthTargeted,
					Note = @Note, IsPresentation = @IsPresentation, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE PresentationID = @PresentationID	
		END

proc_SaveQuestion
CREATE PROCEDURE dbo.proc_SaveQuestion
	(@IsNew BIT, @Question VARCHAR(500), @Outcome VARCHAR(500), @GoalID INT, @MaxRating TINYINT,
	@IsResource BIT, @IsSafety BIT, @IsShelter BIT, @IsServices BIT, @IsCounseling BIT,
	@IsGroup BIT, @IsCurrent BIT,	@UserName VARCHAR(50), @QuestionID INT OUTPUT, 
	@GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Questions
			(Question, Outcome, GoalID, MaxRating, IsSafety, IsResource, IsShelter, IsServices,
			IsCounseling, IsGroup, IsCurrent, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
			VALUES
			(@Question, @Outcome, @GoalID, @MaxRating, @IsSafety, @IsResource, @IsShelter, @IsServices,
			@IsCounseling, @IsGroup, @IsCurrent, @UserName, @UserName, @GetDate, @GetDate)
			SELECT @QuestionID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE Questions
			SET Question = @Question, Outcome = @Outcome, GoalID = @GoalID, MaxRating = @MaxRating, 
			IsSafety = @IsSafety, IsResource = @IsResource, IsShelter = @IsShelter, IsServices = @IsServices,
			IsCounseling = @IsCounseling, IsGroup = @IsGroup, IsCurrent = @IsCurrent, 
			ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE QuestionID = @QuestionID
		END

proc_SaveReportNarrative
CREATE PROCEDURE dbo.proc_SaveReportNarrative
	(@ReportNumber INT, @Item VARCHAR(10), @ReportDate SMALLDATETIME, @Narrative VARCHAR(2000),
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @NarrativeID INT OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @NarrativeID = 0
		BEGIN
			SELECT @NarrativeID = (SELECT TOP 1 NarrativeID FROM ReportNarratives WHERE ReportNumber = @ReportNumber 
				AND Item = @Item AND ReportDate = @ReportDate AND DeletedDate IS NOT NULL)
			IF @NarrativeID IS NULL
				BEGIN
					INSERT INTO ReportNarratives
					(ReportNumber, Item, ReportDate, Narrative, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
					Values
					(@ReportNumber, @Item, @ReportDate, @Narrative, @GetDate, @UserName, @GetDate, @UserName)
					SELECT @NarrativeID = SCOPE_IDENTITY()	
				END
			ELSE
				BEGIN
					UPDATE ReportNarratives
					Set ReportNumber = @ReportNumber, Item = @Item, ReportDate = @ReportDate, Narrative = @Narrative,
						ModifiedBy = @UserName, ModifiedDate = @GetDate, DeletedDate = NULL, DeletedBy = ''
					WHERE ReportNumber = @ReportNumber AND Item = @Item AND ReportDate = @ReportDate
				END
			END
	ELSE
		UPDATE ReportNarratives
		SET ReportNumber = @ReportNumber, Item = @Item, ReportDate = @ReportDate, Narrative = @Narrative,
			ModifiedBy = @UserName, ModifiedDate = @GetDate, DeletedDate = NULL, DeletedBy = ''
		WHERE NarrativeID = @NarrativeID

proc_SaveService
-- Add a FocusID of 0 in ServiceFocus related to a new service, i.e., Focus = 
CREATE PROCEDURE dbo.proc_SaveService
	(@IsNew BIT, @ServiceID INT OUTPUT, @ServiceName VARCHAR(50), @IsGroup BIT, @IsFamily BIT, @InPerson BIT,
	@ByPhone BIT, @DiscontinuedDate SMALLDATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Services
			(ServiceName, IsGroup, IsFamily, InPerson, ByPhone, DiscontinuedDate, 
			CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
			Values
			(@ServiceName, @IsGroup, @IsFamily, @InPerson, @ByPhone, @DiscontinuedDate, 
			@UserName, @UserName, @GetDate, @GetDate)
			SELECT @ServiceID = SCOPE_IDENTITY()
			INSERT INTO ServiceFocus (ServiceID, FocusID) VALUES (@ServiceID, 0)	
		END
	ELSE
		BEGIN
			UPDATE Services
			SET ServiceName = @ServiceName, IsGroup = @IsGroup, IsFamily = @IsFamily, InPerson = @InPerson,
				ByPhone = @ByPhone, DiscontinuedDate = @DiscontinuedDate, ModifiedBy = @UserName, ModifiedDate = @GetDate 
			WHERE ServiceID = @ServiceID 
		END

proc_SaveServiceSession
CREATE PROCEDURE dbo.proc_SaveServiceSession
	(@IsNew BIT, @ProgramID INT, @ServiceID INT, @FocusID INT, @SessionDate SMALLDATETIME, @SessionHours FLOAT, @NumberStaff INT,
	@LocationID INT, @ByPhone BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @SessionID INT OUTPUT)
	AS
	SELECT @GetDate = getdate()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Sessions
			(ProgramID, ServiceID, FocusID, SessionDate, SessionHours, NumberStaff, LocationID, ByPhone, CreatedDate, ModifiedDate, CreatedBy, ModifiedBy)
			Values
			(@ProgramID, @ServiceID, @FocusID, @SessionDate, @SessionHours, @NumberStaff, @LocationID, @ByPhone, @GetDate, @GetDate, @UserName, @UserName)
			SELECT @SessionID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE Sessions
			SET ProgramID = @ProgramID, ServiceID = @ServiceID, FocusID = @FocusID, SessionDate = @SessionDate, SessionHours = @SessionHours, 
			NumberStaff = @NumberStaff, LocationID = @LocationID, ByPhone = @ByPhone, CreatedDate = @GetDate, ModifiedDate = @GetDate, 
			CreatedBy = @UserName, ModifiedBy = @UserName
			WHERE SessionID = @SessionID
			DELETE ClientSessions WHERE SessionID = @SessionID
			DELETE StaffSessions WHERE SessionID = @SessionID
			DELETE Trips WHERE TripID = @SessionID
			DELETE SessionNotes WHERE SessionID = @SessionID
			DELETE TangibleGoods WHERE SessionID = @SessionID
		END

proc_SaveTanfValues
CREATE PROCEDURE dbo.proc_SaveTanfValues
	(@BaseLevel INT, @Increment INT, @PercentFPL INT, @UserName VARCHAR(50))
	AS
	DECLARE @RecordCount INT
	SELECT @RecordCount = COUNT(*) FROM TANF
	IF @RecordCount = 0
		INSERT INTO TANF (LockID, BaseLevel, Increment, PercentFPL, ModifiedDate, ModifiedBy)
			VALUES (1, @BaseLevel, @Increment, @PercentFPL, getdate(), @UserName)
	ELSE
		UPDATE TANF SET BaseLevel = @BaseLevel, Increment = @Increment, PercentFPL = @PercentFPL,
			ModifiedDate = getdate(), ModifiedBy = @UserName
		WHERE LockID = 1

proc_SaveTangibleGoodType
CREATE PROCEDURE proc_SaveTangibleGoodType
	(@IsNew BIT, @GoodTypeID INT OUTPUT, @GoodType VARCHAR(100), @IsCurrent BIT, 
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO xGoodType 
				(GoodType, IsCurrent, CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
			VALUES 
				(@GoodType, @IsCurrent, @UserName, @GetDate, @UserName, @GetDate)
			SELECT @GoodTypeID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE xGoodType
			SET GoodType = @GoodType, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE GoodTypeID = @GoodTypeID
		END

proc_SaveTask
CREATE PROCEDURE dbo.proc_SaveTask
	(@IsNew BIT, @TaskID INT OUTPUT, @TaskName VARCHAR(100), @IntakeTypeID INT,
	@DaysToComplete INT, @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO Tasks
				(Task, IntakeTypeID, DaysToComplete, IsCurrent,
				CreatedBy, CreatedDate, ModifiedBy, ModifiedDate)
				VALUES
				(@TaskName, @IntakeTypeID, @DaysToComplete, @IsCurrent,
				@UserName, @GetDate, @UserName, @GetDate)
			SELECT @TaskID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			UPDATE Tasks
				SET Task = @TaskName, IntakeTypeID = @IntakeTypeID, DaysToComplete = @DaysToComplete,
					IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
				WHERE TaskID = @TaskID
		END

proc_SaveTrainingSession
CREATE PROCEDURE dbo.proc_SaveTrainingSession
	(@IsNew BIT, @SessionID INT OUTPUT, @SubjectID INT, @SessionDate SMALLDATETIME, @SessionHours FLOAT,
	 @PrepHours FLOAT = NULL, @OnSite BIT, @SessionNote VARCHAR(255), @Facilitators VARCHAR(255), @UserName VARCHAR(50),
	 @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	IF @IsNew = 1
		BEGIN
			INSERT INTO TrainingSessions
				(SubjectID, SessionDate, SessionHours, PrepHours, OnSite, SessionNote, Facilitators, CreatedDate, CreatedBy, ModifiedDate, ModifiedBy)
				Values
				(@SubjectID, @SessionDate, @SessionHours, @PrepHours, @OnSite, @SessionNote, @Facilitators, @GetDate, @Username, @GetDate, @UserName)
			SELECT @SessionID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			DELETE FROM StaffTraining WHERE SessionID = @SessionID
			UPDATE TrainingSessions
				Set SubjectID = @SubjectID, SessionDate = @SessionDate, SessionHours = @SessionHours,
					PrepHours = @PrepHours, OnSite = @OnSite, SessionNote = @SessionNote,
					Facilitators = @Facilitators, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE SessionID = @SessionID
		END

proc_SaveVolunteerActivity
CREATE PROCEDURE dbo.proc_SaveVolunteerActivity
	(@IsNew BIT, @ActivityID INT OUTPUT, @Activity VARCHAR(50), @ActivityDate SMALLDATETIME,
	@OneTimeVolunteers INT, @OneTimeHours FLOAT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = GETDATE()
	IF @IsNew = 1
		BEGIN
			INSERT INTO VolunteerActivities
			(Activity, ActivityDate, OneTimeVolunteers, OneTimeHours, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
			Values
			(@Activity, @ActivityDate,@OneTimeVolunteers, @OneTimeHours, @UserName, @UserName, @GetDate, @GetDate)
			SELECT @ActivityID = SCOPE_IDENTITY()
		END
	ELSE
		BEGIN
			DELETE FROM VolunteerActivity WHERE ActivityID = @ActivityID
			UPDATE VolunteerActivities
			SET
				Activity = @Activity, ActivityDate = @ActivityDate, OneTimeVolunteers = @OneTimeVolunteers,  
				OneTimeHours = @OneTimeHours, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE ActivityID = @ActivityID
		END

proc_SearchCalls
CREATE PROCEDURE dbo.proc_SearchCalls
	(@FromDate SMALLDATETIME, @ToDate SMALLDATETIME, @ShelterID INT = NULL,
	@FirstName VARCHAR(50) = NULL, @LastName VARCHAR(50) = NULL, @MI VARCHAR(1) = NULL,
	@NumberChildren INT = NULL, @CallTypeID INT = NULL, @CallSubjectID INT = NULL,
	@ReferralSourceID INT = NULL, @LocationID INT = NULL, @RequestOutcomeID INT = NULL,
	@ReasonDeniedID INT = NULL, @HotlineReferralID INT = NULL)
	AS
	SELECT c.CallID, CallDate, LastName + ', ' + FirstName + ' ' + MI AS Caller,
		CallType, CallSubject, ISNULL(RequestOutcome, 'N/A') AS RequestOutcome, 
		ISNULL(ReasonDenied,'N/A') AS ReasonDenied 
	FROM Calls c LEFT OUTER JOIN ShelterRequests sr ON c.CallID = sr.CallID
		LEFT OUTER JOIN HotlineReferrals hr ON sr.CallID = hr.CallID
		LEFT OUTER JOIN xCallSubject xcs ON xcs.CallSubjectID = c.CallSubjectID
		LEFT OUTER JOIN xCallType xct ON xct.CallTypeID = c.CallTypeID
		LEFT OUTER JOIN xRequestOutcome xro ON xro.RequestOutcomeID = sr.RequestOutcomeID
		LEFT OUTER JOIN xReasonDenied xrd ON xrd.ReasonDeniedID = sr.ReasonDeniedID
	WHERE CallDate BETWEEN @FromDate AND @ToDate AND c.DeletedDate IS NULL
		AND (@ShelterID IS NULL OR c.ShelterID = @ShelterID)
		AND (@NumberChildren IS NULL OR c.NumberChildren = @NumberChildren)
		AND (@CallTypeID IS NULL OR c.CallTypeID = @CallTypeID)
		AND (@CallSubjectID IS NULL OR c.CallSubjectID = @CallSubjectID)
		AND (@ReferralSourceID IS NULL OR c.ReferralSourceID = @ReferralSourceID)
		AND (@LocationID IS NULL OR c.LocationID = @LocationID)
		AND (@RequestOutcomeID IS NULL OR sr.RequestOutcomeID = @RequestOutcomeID)
		AND (@ReasonDeniedID IS NULL OR sr.ReasonDeniedID = @ReasonDeniedID)
		AND (@HotlineReferralID IS NULL OR hr.HotlineReferralID = @HotlineReferralID)
		AND (@FirstName IS NULL OR c.FirstName Like (@FirstName + '%'))
		AND (@LastName IS NULL OR c.LastName Like (@LastName + '%'))
		AND (@MI IS NULL OR c.MI = @MI)
	ORDER BY CallDate

proc_SearchDOB
CREATE PROCEDURE dbo.proc_SearchDOB
	(@ClientTypeID INT, @DOB1 DATETIME, @DOB2 DATETIME)
	AS
	IF @ClientTypeID = 1
		BEGIN
			SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB
			FROM Participants
			WHERE DOB BETWEEN @DOB1 AND @DOB2 AND DeletedDate IS NULL
			ORDER BY FullName
		END
	ELSE IF @ClientTypeID = 2
		BEGIN
			SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB
			FROM Children
			WHERE DOB BETWEEN @DOB1 AND @DOB2 AND DeletedDate IS NULL
			ORDER BY FullName
		END
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB FROM Abusers
			WHERE DOB BETWEEN @DOB1 AND @DOB2 AND DeletedDate IS NULL
			ORDER BY FullName
		END
	ELSE IF @ClientTypeID = 4
		BEGIN
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB FROM CommunityMembers
			WHERE DOB BETWEEN @DOB1 AND @DOB2 AND DeletedDate IS NULL
			ORDER BY FullName
		END

proc_SearchEntryDates
CREATE PROCEDURE dbo.proc_SearchEntryDates
	(@ShelterID INT, @FromDate DATETIME, @ToDate DATETIME, @ClientTypeID INT)
	AS
	IF @ClientTypeID = 1
		BEGIN
			IF @ShelterID > 0
				BEGIN
					SELECT IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, EntryDate
					FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
					WHERE ShelterID = @ShelterID AND EntryDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, EntryDate
					FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
					WHERE EntryDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 2
		BEGIN
			IF @ShelterID > 0
				BEGIN
					SELECT ci.IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ci.EntryDate
					FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
					WHERE ShelterID = @ShelterID AND ci.EntryDate BETWEEN @FromDate AND @ToDate AND c.DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ci.IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ci.EntryDate
					FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
					WHERE ci.EntryDate BETWEEN @FromDate AND @ToDate AND c.DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT a.AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, EntryDate
			FROM AbuserIntakes ai INNER JOIN Abusers a ON ai.AbuserID = a.AbuserID
			WHERE EntryDate BETWEEN @FromDate AND @ToDate AND ai.DeletedDate IS NULL AND a.DeletedDate IS NULL
			ORDER BY FullName
		END

proc_SearchExitDates
CREATE PROCEDURE dbo.proc_SearchExitDates
	(@ShelterID INT, @FromDate DATETIME, @ToDate DATETIME, @ClientTypeID INT)
	AS
	IF @ClientTypeID = 1
		BEGIN
			IF @ShelterID > 0
				BEGIN
					SELECT IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ExitDate
					FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
					WHERE ShelterID = @ShelterID AND ExitDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ExitDate
					FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
					WHERE ExitDate BETWEEN @FromDate AND @ToDate AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 2
		BEGIN
			IF @ShelterID > 0
				BEGIN
					SELECT ci.IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ci.ExitDate
					FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
					WHERE ShelterID = @ShelterID AND ci.ExitDate BETWEEN @FromDate AND @ToDate AND c.DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ci.IntakeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ci.ExitDate
					FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
					WHERE ci.ExitDate BETWEEN @FromDate AND @ToDate AND c.DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT a.AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, ExitDate
			FROM AbuserIntakes ai INNER JOIN Abusers a ON ai.AbuserID = a.AbuserID
			WHERE ExitDate BETWEEN @FromDate AND @ToDate AND ai.DeletedDate IS NULL AND a.DeletedDate IS NULL
			ORDER BY FullName
		END

proc_SearchNamesExact
CREATE PROCEDURE dbo.proc_SearchNamesExact
	(@ClientTypeID INT, @IncludeAlias BIT, @FirstName VARCHAR(50), @MI VARCHAR(1), @LastName VARCHAR(50))
	AS
	IF @ClientTypeID = 1
		BEGIN
			IF @IncludeAlias = 1
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Participants
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					UNION ALL
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI + ' (Alias)' AS FullName FROM Aliases
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Participants
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 2
		BEGIN
			IF @IncludeAlias = 1
				BEGIN
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Children
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					UNION ALL
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (Alias)' AS Fullname FROM ChildAliases
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Children
					WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Abusers
			WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
			ORDER BY FullName
		END
	ELSE IF @ClientTypeID = 4
		BEGIN
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM CommunityMembers
			WHERE FirstName = @FirstName AND MI = @MI AND LastName = @LastName AND DeletedDate IS NULL
			ORDER BY FullName
		END

proc_SearchNamesLike
CREATE PROCEDURE dbo.proc_SearchNamesLike
	(@ClientTypeID INT, @IncludeAlias BIT, @FirstName VARCHAR(50), @MI VARCHAR(1), @LastName VARCHAR(50))
	AS
	IF @ClientTypeID = 1
		BEGIN
			IF @IncludeAlias = 1
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Participants
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					UNION ALL
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI + ' (Alias)' AS FullName FROM Aliases
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Participants
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 2
		BEGIN
			IF @IncludeAlias = 1
				BEGIN
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Children
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					UNION ALL
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI + ' (Alias)' AS FullName FROM ChildAliases
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE
				BEGIN
					SELECT ChildID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Children
					WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE IF @ClientTypeID = 3
		BEGIN
			SELECT AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Abusers
			WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
			ORDER BY FullName
		END
	ELSE IF @ClientTypeID = 4
		BEGIN
			SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName FROM CommunityMembers
			WHERE FirstName LIKE @FirstName + '%' AND MI LIKE @MI + '%' AND LastName LIKE @LastName + '%' AND DeletedDate IS NULL
			ORDER BY FullName
		END

proc_SearchOptionalID
CREATE PROCEDURE dbo.proc_SearchOptionalID
	(@ClientTypeID INT, @ExactMatch BIT, @OptionalID VARCHAR(50))
	AS
	IF @ExactMatch = 1
		BEGIN
			IF @ClientTypeID = 1
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName, OptionalIdentifier
					FROM Participants
					WHERE OptionalIdentifier = @OptionalID AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE IF @ClientTypeID = 4
				BEGIN
					SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName, OptionalIdentifier
					FROM CommunityMembers
					WHERE OptionalIdentifier = @OptionalID AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END
	ELSE 
		BEGIN
			IF @ClientTypeID = 1
				BEGIN
					SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName, OptionalIdentifier
					FROM Participants
					WHERE OptionalIdentifier LIKE @OptionalID + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
			ELSE IF @ClientTypeID = 4
				BEGIN
					SELECT MemberID, LastName + ', ' + FirstName + ' ' + MI AS FullName, OptionalIdentifier
					FROM CommunityMembers
					WHERE OptionalIdentifier LIKE @OptionalID + '%' AND DeletedDate IS NULL
					ORDER BY FullName
				END
		END

proc_SearchSSNExact
CREATE PROCEDURE dbo.proc_SearchSSNExact
	(@SSN VARCHAR(11))
	AS
	SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName, SSN
	FROM Participants
	WHERE SSN = @SSN AND DeletedDate IS NULL
	ORDER BY FullName

proc_SearchSSNLike
CREATE PROCEDURE dbo.proc_SearchSSNLike
	(@SSN1 VARCHAR(3), @SSN2 VARCHAR(2), @SSN3 VARCHAR(4))
	AS
	SELECT ParticipantID, LastName + ', ' + FirstName + ' ' + MI AS FullName, SSN
	FROM Participants
	WHERE SSN LIKE @SSN1 + '%' + '-' + @SSN2 + '%' + '-' + @SSN3 + '%' AND DeletedDate IS NULL
	ORDER BY FullName

proc_UnlinkIntakes
CREATE PROCEDURE dbo.proc_UnlinkIntakes
	(@ParticipantID INT, @IntakeID INT)
	AS
	DELETE FROM LinkedIntakes 
	WHERE ParticipantID = @ParticipantID AND GainingIntakeID = @IntakeID

proc_UnmapService
CREATE PROCEDURE dbo.proc_UnmapService
	(@GrantorID INT, @ServiceFocusID INT)
	AS
	DELETE FROM ServiceMap 
	WHERE GrantorID = @GrantorID And ServiceFocusID = @ServiceFocusID


proc_UpdateAbuser
CREATE PROCEDURE dbo.proc_UpdateAbuser  
	(@AbuserID INT ,@EthnicityID INT, @FirstName VARCHAR(50), @LastName VARCHAR(50), @MI CHAR(1),  
	@TribeID INT, @Sex CHAR(1),@DOB SMALLDATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	UPDATE Abusers  
	Set EthnicityID = @EthnicityID, FirstName = @FirstName, LastName = @LastName, MI = @MI,  
	Sex = @Sex, DOB = @DOB, ModifiedDate = @GetDate, ModifiedBy = @UserName  
	WHERE AbuserID = @AbuserID  
	DELETE FROM TribalAffiliation WHERE ClientID = @AbuserID And ClientTypeID = 3
	IF @EthnicityID IN (7,8) AND @TribeID > 0
		INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@AbuserID, 3, @TribeID)	 

proc_UpdateAlias
CREATE PROCEDURE dbo.proc_UpdateAlias
	(@AliasID INT, @ParticipantID INT, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50),
	 @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Aliases
		Set ParticipantID = @ParticipantID, FirstName = @FirstName, MI = @MI, LastName = @LastName,
		ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE AliasID = @AliasID
	RETURN


proc_UpdateBed
CREATE PROCEDURE dbo.proc_UpdateBed
	(@BedID INT OUTPUT, @ShelterID INT, @Description VARCHAR(50), @IsCrib BIT, @ServiceStart SMALLDATETIME, @ServiceEnd SMALLDATETIME, 
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	IF 	(SELECT TOP 1 IntakeID 
		FROM IntakeBeds ib INNER JOIN Beds b ON ib.BedID = b.BedID
		WHERE ib.BedID = @BedID AND b.ShelterID <> @ShelterID) IS NULL
	BEGIN	
		UPDATE Beds
			Set ShelterID = @ShelterID, Description = @Description, IsCrib = @IsCrib, 
			ServiceStart = @ServiceStart, ServiceEnd = @ServiceEnd,
			ModifiedBy = @UserName, ModifiedDate = @GetDate
		WHERE BedID = @BedID
	END
	ELSE SELECT @BedID = -1

proc_UpdateCampus
CREATE PROCEDURE dbo.proc_UpdateCampus
	(@CampusName VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT,
	 @CampusID INT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Campuses
	SET CampusName = @CampusName, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE CampusID = @CampusID
	RETURN

proc_UpdateChild
CREATE PROCEDURE dbo.proc_UpdateChild  
	(@ChildID INT, @ParticipantID INT, @EthnicityID INT, @TribeID INT, @FirstName VARCHAR(50), @LastName VARCHAR(50), @MI CHAR(1),  
	@Sex CHAR(1),@DOB SMALLDATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	UPDATE Children  
	Set ParticipantID = @ParticipantID, EthnicityID = @EthnicityID, FirstName = @FirstName, LastName = @LastName, MI = @MI,  
	Sex = @Sex, DOB = @DOB, ModifiedDate = @GetDate, ModifiedBy = @UserName  
	WHERE ChildID = @ChildID
	DELETE FROM TribalAffiliation WHERE ClientID = @ChildID And ClientTypeID = 2
	IF @EthnicityID IN (7,8) AND @TribeID > 0
		INSERT INTO TribalAffiliation (ClientID, ClientTypeID, TribeID) Values (@ChildID, 2, @TribeID)

proc_UpdateChildAlias
CREATE PROCEDURE dbo.proc_UpdateChildAlias
	(@AliasID INT, @ChildID INT, @FirstName VARCHAR(50), @MI CHAR(1), @LastName VARCHAR(50),
	 @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE ChildAliases
		Set ChildID = @ChildID, FirstName = @FirstName, MI = @MI, LastName = @LastName,
		ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE AliasID = @AliasID

proc_UpdateCredential
CREATE PROCEDURE dbo.proc_UpdateCredential
	(@CredentialID INT, @Credential VARCHAR(50), @Frequency INT, @IsSubject BIT,
	 @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Credentials
		Set Credential = @Credential, Frequency = @Frequency, IsSubject = @IsSubject,
			IsCurrent = @IsCurrent, ModifiedBy = @UserName
	WHERE CredentialID = @CredentialID
	RETURN

proc_UpdateEmerContact
CREATE PROCEDURE dbo.proc_UpdateEmerContact  
	(@EmerContactID INT, @ParticipantID INT, @ContactName VARCHAR(100), @Relationship VARCHAR(50), @Address VARCHAR(100),  
	@City VARCHAR(50), @State VARCHAR(50), @Zip VARCHAR(10), @Phone VARCHAR(15), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)  
	AS  
	SELECT @GetDate = getdate()  
	UPDATE EmerContacts  
	Set ParticipantID = @ParticipantID, ContactName = @ContactName, Relationship = @Relationship, Address = @Address, City = @City,  
	State = @State, Zip = @Zip, Phone = @Phone, ModifiedDate = @GetDate, ModifiedBy = @UserName  
	WHERE EmerContactID = @EmerContactID  
	RETURN

proc_UpdateFocus
-- Fix the problem with updating/adding ServiceFocus when the service as focus(es) already mapped
CREATE PROCEDURE dbo.proc_UpdateFocus
	(@FocusID INT, @Focus VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Focus
	SET Focus = @Focus, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE FocusID = @FocusID
	DELETE FROM ServiceMap 
		WHERE ServiceFocusID IN (SELECT ServiceFocusID FROM ServiceFocus WHERE FocusID = @FocusID) 
	DELETE FROM ServiceFocus WHERE FocusID = @FocusID

proc_UpdateGrant
CREATE PROCEDURE dbo.proc_UpdateGrant
	(@GrantID INT, @GrantorID INT, @ContractNumber VARCHAR(50), @GrantStart SMALLDATETIME, 
	@GrantEnd SMALLDATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @Prorate FLOAT = 1)
	AS
	SELECT @GetDate = getdate()
	UPDATE Grants
	SET GrantorID = @GrantorID, ContractNumber = @ContractNumber, GrantStart = @GrantStart, 
		GrantEnd = @GrantEnd, ModifiedBy = @UserName, ModifiedDate = @GetDate, Prorate = @Prorate 
	WHERE GrantID = @GrantID
	DELETE FROM GrantTargets WHERE GrantID = @GrantID
	DELETE FROM GrantSurveys WHERE GrantID = @GrantID

proc_UpdateIntake
-- Add IsHighRisk to procedure for saving intake records
CREATE PROCEDURE dbo.proc_UpdateIntake 
	(@ParticipantID INT, @ShelterID INT, @IntakeTypeID INT, @AbuserRelationshipID INT, @MaritalStatusID INT, @LanguageID INT, @CitizenshipID INT, @ReligionID INT, @EmploymentExitID INT,
	@CountyID INT, @ReservationID INT, @SubstanceAbuseID INT, @SubstanceTreatmentID INT, @LocationID INT, @CourtOutcomeID INT, @ExitDestinationID INT, @ExitReasonID INT, @ExitHousingID INT, 
	@EmploymentID INT, @PriorResidenceID INT, @IsContinuation BIT, @EntryDate SMALLDATETIME, @ExitDate SMALLDATETIME, @PoliceReport BIT, @DVArrestClient BIT, @DVArrestBatterer BIT, @PreviousReport BIT, 
	@PreviousArrestClient BIT, @PreviousArrestBatterer BIT, @CurrentProtectionOrder BIT, @PreviousProtectionOrder BIT, @EmergencyMedClient BIT, @EmergencyMedBatterer BIT, @CourtCase BIT, 
	@ProtectionOrder BIT, @ExtensionWavier BIT, @TANF_Eligible BIT, @IncomeEntry INT, @IncomeExit INT, @SSI BIT, @SSDI BIT, @SS BIT, @GenPubAssistance BIT, @TANF BIT, @ChildSupport BIT, 
	@VetBenefits BIT, @EmploymentIncome BIT, @UnemploymentBenefits BIT, @Medicare BIT, @Medicaid BIT, @FoodStamps BIT, @NoFinancialResources BIT, @WIC BIT, @LowIncomeHousing BIT, @KidsCare BIT, 
	@AHCCCS BIT, @CashAssistance BIT, @SSIExit BIT, @SSDIExit BIT, @SSExit BIT, @GenPubAssistanceExit BIT, @TANFExit BIT, @ChildSupportExit BIT, @VetBenefitsExit BIT, @EmploymentIncomeExit BIT, 
	@UnemploymentBenefitsExit BIT, @MedicareExit BIT, @MedicaidExit BIT, @FoodStampsExit BIT, @NoFinancialResourcesExit BIT, @WICExit BIT, @LowIncomeHousingExit BIT, @KidsCareExit BIT, 
	@AHCCCSExit BIT, @CashAssistanceExit BIT, @HealthStatus VARCHAR(50), @HealthComments VARCHAR(150), @Medication BIT, @MentalIllness BIT, @PhysDisability BIT, @DevDisability BIT, @HIVAIDS BIT, 
	@Pregnant BIT, @PreviousMedDiscussion BIT, @PregnantDuringDV BIT, @MiscarriageDuringDV BIT, @AbusePhysical BIT, @AbuseSexual BIT, @AbuseVerbalPsychological BIT, @AbuseEconomic BIT, 
	@AbusedAsChild BIT, @AbuseWitness BIT, @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(15), @Zip VARCHAR(15), @Phone VARCHAR(50), @YearsSchooling INT, @NumberChildren INT, 
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @IntakeID INT, @EntryDataComplete BIT, @ExitDataComplete BIT, @IncomeOther VARCHAR(100), @IncomeOtherExit VARCHAR(100), @LastAbuseDate SMALLDATETIME,
	@Allergies BIT, @ChronicHealthCondition BIT, @Deaf BIT, @PermanentSafeHousing BIT, @StillInRelationship BIT, @IsAbuserVeteran BIT, @ReferralSourceID INT,
	@IncomeIncreased BIT = 0, @EducationGoals BIT = 0, @EducationImproved BIT = 0, @HealthPlanGoals BIT = 0, @HealthImproved BIT = 0, @HasSafetyPlan BIT = 0, @AccessResources BIT = 0,
	@ServicesHelped BIT = 0, @EmployedAfterExit BIT = 0, @SafeHousing BIT = 0, @ThreeMonthContact BIT = 0, @ThreeMonthSafelyHoused BIT = 0, @IsHighRisk BIT = 0) 
	AS
	DELETE FROM IntakeVictimType WHERE IntakeID = @IntakeID 
	DELETE FROM IntakeStaff WHERE IntakeID = @IntakeID
	DELETE FROM IntakePhase WHERE IntakeID = @IntakeID
	DELETE FROM Pets WHERE IntakeID = @IntakeID
	DELETE FROM IntakeTasks WHERE IntakeID = @IntakeID AND ClientTypeID = 1
	SELECT @GetDate = getdate() 
	UPDATE Intakes 
	Set ParticipantID = @ParticipantID, ShelterID = @ShelterID, IntakeTypeID = @IntakeTypeID, AbuserRelationshipID = @AbuserRelationshipID, 
	MaritalStatusID = @MaritalStatusID, LanguageID = @LanguageID, CitizenshipID = @CitizenshipID, ReligionID = @ReligionID, CountyID = @CountyID, ReservationID = @ReservationID, SubstanceAbuseID = @SubstanceAbuseID, 
	SubstanceTreatmentID = @SubstanceTreatmentID, LocationID = @LocationID, CourtOutcomeID = @CourtOutcomeID, ExitDestinationID = @ExitDestinationID, ExitReasonID = @ExitReasonID, 
	ExitHousingID = @ExitHousingID, EmploymentID = @EmploymentID, PriorResidenceID = @PriorResidenceID, IsContinuation = @IsContinuation, EntryDate = @EntryDate, ExitDate = @ExitDate, PoliceReport = @PoliceReport, 
	DVArrestClient = @DVArrestClient, DVArrestBatterer = @DVArrestBatterer, PreviousReport = @PreviousReport, PreviousArrestClient = @PreviousArrestClient, PreviousArrestBatterer = @PreviousArrestBatterer, 
	CurrentProtectionOrder = @CurrentProtectionOrder, PreviousProtectionOrder = @PreviousProtectionOrder, EmergencyMedClient = @EmergencyMedClient, EmergencyMedBatterer = @EmergencyMedBatterer, 
	CourtCase = @CourtCase, ProtectionOrder = @ProtectionOrder, ExtensionWavier = @ExtensionWavier, TANF_Eligible = @TANF_Eligible, IncomeEntry = @IncomeEntry, IncomeExit = @IncomeExit, SSI = @SSI, 
	SSDI = @SSDI, SS = @SS, GenPubAssistance = @GenPubAssistance, TANF = @TANF, ChildSupport = @ChildSupport, VetBenefits = @VetBenefits, EmploymentIncome = @EmploymentIncome, 
	UnemploymentBenefits = @UnemploymentBenefits, Medicare = @Medicare, Medicaid = @Medicaid, FoodStamps = @FoodStamps, NoFinancialResources = @NoFinancialResources, WIC = @WIC, 
	LowIncomeHousing = @LowIncomeHousing, KidsCare = @KidsCare, AHCCCS = @AHCCCS, CashAssistance = @CashAssistance, SSIExit = @SSIExit, SSDIExit = @SSDIExit, SSExit = @SSExit, EmploymentExitID = @EmploymentExitID,
	GenPubAssistanceExit = @GenPubAssistanceExit, TANFExit = @TANFExit, ChildSupportExit = @ChildSupportExit, VetBenefitsExit = @VetBenefitsExit, EmploymentIncomeExit = @EmploymentIncomeExit, 
	UnemploymentBenefitsExit = @UnemploymentBenefitsExit, MedicareExit = @MedicareExit, MedicaidExit = @MedicaidExit, FoodStampsExit = @FoodStampsExit, NoFinancialResourcesExit = @NoFinancialResourcesExit, 
	WICExit = @WICExit, LowIncomeHousingExit = @LowIncomeHousingExit, KidsCareExit = @KidsCareExit, AHCCCSExit = @AHCCCSExit, CashAssistanceExit = @CashAssistanceExit, HealthStatus = @HealthStatus, 
	HealthComments = @HealthComments, Medication = @Medication, MentalIllness = @MentalIllness, PhysDisability = @PhysDisability, DevDisability = @DevDisability, HIVAIDS = @HIVAIDS, Pregnant = @Pregnant, 
	PreviousMedDiscussion = @PreviousMedDiscussion, PregnantDuringDV = @PregnantDuringDV, MiscarriageDuringDV = @MiscarriageDuringDV, AbusePhysical = @AbusePhysical, AbuseSexual = @AbuseSexual, 
	AbuseVerbalPsychological = @AbuseVerbalPsychological, AbuseEconomic = @AbuseEconomic, AbusedAsChild = @AbusedAsChild, AbuseWitness = @AbuseWitness, Address = @Address, City = @City, State = @State, 
	Zip = @Zip, Phone = @Phone, YearsSchooling = @YearsSchooling, NumberChildren = @NumberChildren, ModifiedDate = @GetDate, ModifiedBy = @UserName, EntryDataComplete = @EntryDataComplete,
	ExitDataComplete = @ExitDataComplete, IncomeOther = @IncomeOther, IncomeOtherExit = @IncomeOtherExit, LastAbuseDate = @LastAbuseDate, Allergies = @Allergies, ChronicHealthCondition = @ChronicHealthCondition,
	Deaf = @Deaf, PermanentSafeHousing = @PermanentSafeHousing, StillInRelationship = @StillInRelationship, IsAbuserVeteran = @IsAbuserVeteran, ReferralSourceID = @ReferralSourceID,
	IncomeIncreased = @IncomeIncreased, EducationGoals = @EducationGoals, EducationImproved = @EducationImproved, HealthPlanGoals = @HealthPlanGoals, HealthImproved = @HealthImproved,
	HasSafetyPlan = @HasSafetyPlan, AccessResources = @AccessResources, ServicesHelped = @ServicesHelped, EmployedAfterExit = @EmployedAfterExit, SafeHousing = @SafeHousing,
	ThreeMonthContact = @ThreeMonthContact, ThreeMonthSafelyHoused = @ThreeMonthSafelyHoused, IsHighRisk = @IsHighRisk
	WHERE IntakeID = @IntakeID
	IF @ExitDate IS NOT NULL
		BEGIN
			UPDATE IntakeBeds 
			SET DateOut = @ExitDate, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE IntakeID = @IntakeID AND ClientTypeID = 1 AND DateOut IS NULL
			UPDATE IntakePhase
			SET CompletedDate = @ExitDate
			WHERE IntakeID = @IntakeID AND CompletedDate IS NULL
		END
	IF @IsContinuation = 0
		BEGIN
			DELETE FROM LinkedIntakes WHERE ParticipantID = @ParticipantID AND GainingIntakeID = @IntakeID
		END

proc_UpdateIntakeBed
CREATE PROCEDURE dbo.proc_UpdateIntakeBed
	(@IntakeID INT, @ClientTypeID INT, @BedID INT, @DateIn SMALLDATETIME, @DateOut SMALLDATETIME,
	 @UserName VARCHAR(50))
	AS
	IF (SELECT TOP 1 IntakeID 
			FROM IntakeBeds
			WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID 
				AND DateIn = @DateIn AND BedID <> @BedID) IS NOT NULL
		BEGIN
			DELETE FROM IntakeBeds 
			WHERE IntakeID = @IntakeID AND ClientTypeID = @ClientTypeID AND DateIn = @DateIn
			INSERT INTO IntakeBeds 
				(IntakeID, ClientTypeID, BedID, DateIn, DateOut, CreatedBy, ModifiedBy, CreatedDate, ModifiedDate)
				Values
				(@IntakeID, @ClientTypeID, @BedID, @DateIn, @DateOut, @UserName, @UserName, getdate(), getdate())
		END
	ELSE
		UPDATE IntakeBeds
			Set DateOut = @DateOut, ModifiedBy = @UserName, ModifiedDate = getdate()
		WHERE IntakeID = @IntakeID And ClientTypeID = @ClientTypeID And DateIn = @DateIn

proc_UpdateNote
CREATE PROCEDURE dbo.proc_UpdateNote
	(@NoteID INT, @ClientID INT, @ClientTypeID INT, @NoteDate SMALLDATETIME, @Subject VARCHAR(50),
	@NoteText VARCHAR(2000), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Notes
	Set ClientID = @ClientID, ClientTypeID = @ClientTypeID, NoteDate = @NoteDate, Subject = @Subject,
		NoteText = @NoteText, ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE NoteID = @NoteID

proc_UpdateProgram
CREATE PROCEDURE dbo.proc_UpdateProgram
	(@ProgramID INT, @Program VARCHAR(100), @IsCurrent BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Programs
	SET Program = @Program, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE ProgramID = @ProgramID
	DELETE FROM ProgramServices WHERE ProgramID = @ProgramID
	RETURN

proc_UpdatePrompts
CREATE PROCEDURE dbo.proc_UpdatePrompts
	(@MaxDaysToComplete INT, @MaxDaysInactive INT, @MaxDaysSinceCall INT)
	AS
	UPDATE zsSettings
	SET MaxDaysToComplete = @MaxDaysToComplete, MaxDaysInactive = @MaxDaysInactive, MaxDaysSinceCall = @MaxDaysSinceCall

proc_UpdateQuestionnaire
CREATE PROCEDURE dbo.proc_UpdateQuestionnaire
	(@SurveyID INT, @IntakeID INT, @CompletedDate DATETIME, @ControlNumber VARCHAR(50), @QuestionnaireID INT, 
	 @ClientTypeID INT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate();
			UPDATE Questionnaires
			SET SurveyID = @SurveyID, IntakeID = @IntakeID, CompletedDate = @CompletedDate, ControlNumber = @ControlNumber, 
			ClientTypeID = @ClientTypeID, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE QuestionnaireID = @QuestionnaireID
			DELETE FROM QuestionResponses WHERE QuestionnaireID = @QuestionnaireID
			DELETE FROM NarrativeResponses WHERE QuestionnaireID = @QuestionnaireID

proc_UpdateReferral
CREATE PROCEDURE dbo.proc_UpdateReferral
	(@ReferralID INT, @ClientID INT, @ClientTypeID INT, @IntakeID INT, @ReferralTypeID INT, @ReferralDate SMALLDATETIME, 
	 @NumberReferrals INT, @Agency VARCHAR(50), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Referrals
	SET 
	ClientID = @ClientID, ClientTypeID = @ClientTypeID, IntakeID = @IntakeID, ReferralTypeID = @ReferralTypeID, 
	ReferralDate = @ReferralDate, NumberReferrals = @NumberReferrals, Agency = @Agency, ModifiedDate = @GetDate, ModifiedBy = @UserName
	WHERE ReferralID = @ReferralID
	DELETE FROM StaffReferrals WHERE ReferralID = @ReferralID

proc_UpdateRoom
CREATE PROCEDURE dbo.proc_UpdateRoom
	(@RoomID INT OUTPUT, @ShelterID INT, @RoomNumber VARCHAR(50), @ServiceStart SMALLDATETIME, @ServiceEnd SMALLDATETIME, 
	@UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	IF (SELECT TOP 1 IntakeID
		FROM IntakeBeds ib INNER JOIN RoomBedAssignments rba ON ib.BedID = rba.BedID
			INNER JOIN Rooms r ON rba.RoomID = r.RoomID
		WHERE r.RoomID = @RoomID AND r.ShelterID <> @ShelterID) IS NULL
	BEGIN
		UPDATE Rooms
			Set ShelterID = @ShelterID, RoomNumber = @RoomNumber, ServiceStart = @ServiceStart, ServiceEnd = @ServiceEnd,
			ModifiedBy = @UserName, ModifiedDate = @GetDate
		WHERE RoomID = @RoomID
	END
	ELSE SELECT @RoomID = -1

proc_UpdateRoomBedAssignment
CREATE PROCEDURE dbo.proc_UpdateRoomBedAssignment
	(@BedID INT, @RoomID INT, @DateAssigned SMALLDATETIME, @DateMoved SMALLDATETIME,
	 @UserName VARCHAR(50), @GetDate DATETIME OUTPUT, @RoomBedAssignmentID INT)
	AS
	SELECT @GetDate = getdate()
	UPDATE RoomBedAssignments
	SET BedID = @BedID, RoomID = @RoomID, DateAssigned = @DateAssigned, DateMoved = @DateMoved,
		ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE RoomBedAssignmentID = @RoomBedAssignmentID
	RETURN

proc_UpdateShelter
CREATE PROCEDURE dbo.proc_UpdateShelter
	(@CampusID INT, @ShelterName VARCHAR(100), @HousingTypeID INT, @IsCurrent BIT, @IsLicensed BIT, @ShelterTypeID INT, 
	 @Residential BIT, @NonResidential BIT, @Hotline BIT, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT,
	 @ShelterID INT)
	AS
	SELECT @GetDate = getdate() 
	UPDATE Shelters
		Set CampusID = @CampusID, ShelterName = @ShelterName, HousingTypeID = @HousingTypeID, IsCurrent = @IsCurrent, IsLicensed = @IsLicensed, 
			ShelterTypeID = @ShelterTypeID, Residential = @Residential, NonResidential = @NonResidential, 
			Hotline = @Hotline, ModifiedBy = @UserName, ModifiedDate = @GetDate 
	WHERE ShelterID = @ShelterID
	RETURN

proc_UpdateStaffMember
CREATE PROCEDURE dbo.proc_UpdateStaffMember
	(@StaffID INT, @FirstName VARCHAR(50), @MI VARCHAR(1), @LastName VARCHAR(50), @Title VARCHAR(50), 
	@ServiceProvider BIT, @Status INT, @DateLeft DATETIME, @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE Staff
	SET 
		FirstName = @FirstName, MI = @MI, LastName = @LastName, Title = @Title, ServiceProvider = @ServiceProvider,
		Status = @Status, DateLeft = @DateLeft, ModifiedBy = @UserName, ModifiedDate = @GetDate
	WHERE StaffID = @StaffID
	DELETE FROM StaffRequirements WHERE StaffID = @StaffID

proc_UpdateStaffMemberExt
CREATE PROCEDURE dbo.proc_UpdateStaffMemberExt
	(@StaffID INT, @Address VARCHAR(100), @City VARCHAR(50), @State VARCHAR(50), @Zip VARCHAR(10),
	@WorkPhone VARCHAR(50), @Ext VARCHAR(10), @MobilePhone VARCHAR(50), @HomePhone VARCHAR(50),
	@Email VARCHAR(100), @DOB SMALLDATETIME, @HireDate SMALLDATETIME, @LastEvalDate SMALLDATETIME,
	@Rehire BIT, @RehireComment VARCHAR(100), @UserName VARCHAR(50), @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate()
	UPDATE StaffExt
	SET
		Address = @Address, City = @City, State = @State, Zip = @Zip, WorkPhone = @WorkPhone,
		Ext = @Ext, MobilePhone = @MobilePhone, HomePhone = @HomePhone, Email = @Email,
		DOB = @DOB, HireDate = @HireDate, LastEvalDate = @LastEvalDate, Rehire = @Rehire,
		RehireComment = @RehireComment, ModifiedDate = @GetDate, ModifiedBy = @UserName
	WHERE StaffID = @StaffID

proc_UpdateStaffRequirement
CREATE PROCEDURE dbo.proc_UpdateStaffRequirement
	(@StaffID INT, @RequirementID INT, @CompletedDate SMALLDATETIME)
	AS
	DECLARE @Frequency INT
	SET @Frequency = (SELECT Top 1 Frequency FROM Credentials WHERE CredentialID = @RequirementID)
	IF @Frequency = -1 -- Manual Expiration
		BEGIN
			UPDATE StaffRequirements 
			SET CompletedDate = @CompletedDate
			WHERE StaffID = @StaffID And RequirementID = @RequirementID
		END
	ELSE IF @Frequency = 0 -- One-time requirement
		BEGIN
			UPDATE StaffRequirements
			SET CompletedDate = @CompletedDate, DueDate = '6/1/2079'
			WHERE StaffID = @StaffID And RequirementID = @RequirementID			
		END
	ELSE IF @Frequency > 0 -- Months until due
		BEGIN
			UPDATE StaffRequirements
			SET CompletedDate = @CompletedDate, DueDate = DATEADD(month, @Frequency, @CompletedDate)
			WHERE StaffID = @StaffID And RequirementID = @RequirementID
		END

proc_UpdateSurvey
CREATE PROCEDURE dbo.proc_UpdateSurvey
	(@SurveyID INT, @SurveyName VARCHAR(50), @IsCurrent BIT, @IsAnonymous BIT, @UserName VARCHAR(50), @Success BIT OUTPUT, @GetDate DATETIME OUTPUT)
	AS
	SELECT @GetDate = getdate();
	IF EXISTS (SELECT SurveyID FROM Surveys WHERE SurveyName = @SurveyName And SurveyID <> @SurveyID)
		SELECT @Success = 0 -- Don't allow an update when the survey name matches an existing survey
	ELSE
		BEGIN
			UPDATE Surveys
			SET SurveyName = @SurveyName, IsCurrent = @IsCurrent, IsAnonymous = @IsAnonymous, ModifiedBy = @UserName, ModifiedDate = @GetDate
			WHERE SurveyID = @SurveyID
			DELETE FROM SurveyQuestions WHERE SurveyID = @SurveyID
			DELETE FROM GrantSurveys WHERE SurveyID = @SurveyID
			DELETE FROM SurveyNarratives WHERE SurveyID = @SurveyID AND NarrativeID NOT IN
				(SELECT NarrativeID
				FROM NarrativeResponses nr INNER JOIN Questionnaires q ON nr.QuestionnaireID = q.QuestionnaireID
				WHERE q.SurveyID = @SurveyID)
			SELECT @Success = 1
		END

proc_UpdateTopic
CREATE PROCEDURE dbo.proc_UpdateTopic
	(@TopicID INT, @IsCurrent BIT, @Topic VARCHAR(100), @UserName VARCHAR(50))
	AS
	UPDATE xTopic
		SET Topic = @Topic, IsCurrent = @IsCurrent, ModifiedBy = @UserName, ModifiedDate = getdate()
	WHERE TopicID = @TopicID

rpt_AbuserServices
CREATE PROCEDURE dbo.rpt_AbuserServices
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Services
    SELECT a.AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, Ethnicity, Sex, ISNULL(Tribe, '') AS Tribe,
    EntryDate, ExitDate, CounselingStatus, CounselingResult, SessionDate, ServiceName,
    ISNULL(SessionHours, 0) AS SessionHours, ISNULL(NumberStaff, 0) AS NumberStaff,
    a.DOB, DATEDIFF(year, DOB, @StartDate) AS Age
    FROM xTribe xt INNER JOIN TribalAffiliation ta ON xt.TribeID = ta.TribeID
        RIGHT OUTER JOIN Abusers a ON a.AbuserID = ta.ClientID AND ta.ClientTypeID = 3
        INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
        INNER JOIN xEthnicity xe ON a.EthnicityID = xe.EthnicityID
        INNER JOIN xCounselingStatus xc ON ai.CounselingStatusID = xc.CounselingStatusID
        INNER JOIN xCounselingResult xr ON ai.CounselingResultID = xr.CounselingResultID
        LEFT OUTER JOIN ClientSessions cs ON a.AbuserID = cs.ClientID AND cs.ClientTypeID = 3
        LEFT OUTER JOIN [Sessions] ss ON cs.SessionID = ss.SessionID AND SessionDate BETWEEN @StartDate AND @EndDate
        LEFT OUTER JOIN Services s ON ss.ServiceID = s.ServiceID
    WHERE a.DeletedDate IS NULL AND ai.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL
        AND ai.EntryDate <= @EndDate AND (ai.ExitDate IS NULL OR ai.ExitDate >= @StartDate)
    ORDER BY FullName, SessionDate;
	-- Abuser intakes during report period
    SELECT a.AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, Ethnicity, Sex, ISNULL(Tribe, '') AS Tribe,
        EntryDate, ExitDate, CounselingStatus, CounselingResult, a.DOB, DATEDIFF(year, DOB, @StartDate) AS Age
    FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
        INNER JOIN xEthnicity xe ON a.EthnicityID = xe.EthnicityID
        INNER JOIN xCounselingStatus xc ON ai.CounselingStatusID = xc.CounselingStatusID
        INNER JOIN xCounselingResult xr ON ai.CounselingResultID = xr.CounselingResultID
        LEFT OUTER JOIN TribalAffiliation ta ON a.AbuserID = ta.ClientID AND ta.ClientTypeID = 3
        LEFT OUTER JOIN xTribe xt ON xt.TribeID = ta.TribeID
    WHERE a.DeletedDate IS NULL AND ai.DeletedDAte IS NULL AND
        a.AbuserID IN
        (SELECT AbuserID FROM AbuserIntakes
        WHERE EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate))
    ORDER BY FullName, EntryDate DESC;

rpt_AbuserStatus
CREATE PROCEDURE dbo.rpt_AbuserStatus
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	SELECT a.AbuserID, LastName + ', ' + FirstName + ' ' + MI AS FullName, EntryDate, ExitDate, Sex,
        ai.CounselingStatusID, CounselingStatus, ai.CounselingResultID, CounselingResult
    FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
        INNER JOIN xCounselingStatus xcs ON xcs.CounselingStatusID = ai.CounselingStatusID
        INNER JOIN xCounselingResult xcr ON xcr.CounselingResultID = ai.CounselingResultID
    WHERE ai.EntryDate < @EndDate AND
        (ai.ExitDate IS NULL OR ai.ExitDate BETWEEN @StartDate AND @EndDate)
        AND a.DeletedDate IS NULL AND ai.DeletedDate IS NULL
    ORDER BY ai.CounselingStatusID, ai.CounselingResultID, FullName;

rpt_ACJC
CREATE PROCEDURE rpt_ACJC
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Victims served
        -- Callers w/o associated intake
        SELECT CallSubjectID AS VictimTypeID, EthnicityID = -1, Age = -1, EntryDate = NULL, DOB = NULL, Sex, Disability = -1,
            c.CallID + 2000000 AS ClientID, IntakeID = -1
        FROM Calls c LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
        WHERE CallSubjectID BETWEEN 3 AND 99 AND ic.IntakeID IS NULL
            AND c.DeletedDate IS NULL AND CallDate BETWEEN @StartDate AND @EndDate
            AND c.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
        -- Participant victims with intake during period
        SELECT ivt.VictimTypeID, p.EthnicityID, DATEDIFF(year, p.DOB, i.EntryDate) AS Age, i.EntryDate, p.DOB, p.Sex,  Disability = CASE
            WHEN MentalIllness = 1 OR physDisability = 1 OR DevDisability = 1 OR HIVAIDS = 1 OR ChronicHealthCondition = 1 THEN 1 ELSE 0 END,
            p.ParticipantID AS ClientID, i.IntakeID
        FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL
            AND EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
            UNION ALL
        -- Children of participant victims with associated child intake
        SELECT ivt.VictimTypeID, c.EthnicityID, DATEDIFF(year, c.DOB, i.EntryDate) AS Age, ci.EntryDate, c.DOB, c.Sex,  Disability = CASE
            WHEN ci.MentalIllness = 1 OR ci.PhysDisability = 1 OR ci.DevDisability = 1 OR ci.HIVAIDS = 1 THEN 1 ELSE 0 END,
            c.ChildID + 1000000 AS ClientID, ci.ChildIntakeID
        FROM Intakes i INNER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL
            AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND c.DeletedDate IS NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
		UNION ALL
		-- Community Client Victims
		SELECT VictimTypeID, cm.EthnicityID, Age = CASE
			WHEN DOB IS NULL THEN -1
			ELSE DATEDIFF(year, DOB, @StartDate) END,
			EntryDate = NULL, DOB, Sex, Disability = -1, 
			MemberID + 3000000 AS ClientID, IntakeID = -1
		FROM CommunityMembers cm
		WHERE VictimTypeID > 2 AND DeletedDate IS NULL
			AND 
				(SELECT TOP 1 ClientID
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID
				WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
					AND ClientID = cm.MemberID AND cs.ClientTypeID = 4
					AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL) IS NOT NULL
        ORDER BY ClientID, VictimTypeID;

    -- Services provided
        -- PARTICIPANT SERVICES mapped to shelter services
        SELECT sm.GrantorServiceID, Contacts = 1
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 501 AND 517
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND ivt.VictimTypeID IS NOT NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        -- CHILDREN SERVICES
        UNION ALL
        SELECT sm.GrantorServiceID, Contacts = 1
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 501 AND 517
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND ivt.VictimTypeID IS NOT NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
		-- COMMUNITY CLIENT SERVICES mapped to shelter services
		SELECT sm.GrantorServiceID, Contacts = 1
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND cs.ClientTypeID = 4 AND cm.VictimTypeID > 2
			AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND sm.GrantorServiceID BETWEEN 501 AND 517
		UNION ALL
        -- PARTICIPANT REFERRALS, use GrantorServiceID = 519
        SELECT GrantorServiceID = 519, NumberReferrals AS Contacts
        FROM Referrals r INNER JOIN Intakes i ON r.IntakeID = i.IntakeID AND r.ClientTypeID = 1
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL
            AND ivt.VictimTypeID IS NOT NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
        -- CHILD REFERRALS, use GrantorServiceID = 519    
        SELECT GrantorServiceID = 519, NumberReferrals AS Contacts
        FROM Referrals r INNER JOIN ChildIntakes ci ON r.IntakeID = ci.ChildIntakeID AND r.ClientTypeID = 2
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL
            AND ivt.VictimTypeID IS NOT NULL
            AND i.ShelterID IN


            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
		UNION ALL
		-- COMMUNITY CLIENT REFERRALS, use GrantorServiceID = 519
		SELECT GrantorServiceID = 519, r.NumberReferrals AS Contacts
		FROM Referrals r INNER JOIN CommunityMembers cm ON r.ClientID = cm.MemberID
		WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
			AND r.ClientTypeID = 4 AND cm.VictimTypeID > 2
			AND r.DeletedDate IS NULL AND cm.DeletedDate IS NULL
        UNION ALL
        -- CRISIS COUNSELING VIA HOTLINE:  treat as Crisis Intervention Services (501)
        SELECT GrantorServiceID = 501, Contacts = 1
        FROM Calls c
        WHERE CallDate BETWEEN @StartDate AND @EndDate
            AND CallSubjectID BETWEEN 3 AND 99 AND CallTypeID IN (1, 3) AND DeletedDate IS NULL
            AND c.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
        -- INFO/REFERRAL HOTLINE CALLS:  treat as Referral (519)
        SELECT GrantorServiceID = 519, Contacts = 1
        FROM Calls c
        WHERE CallDate BETWEEN @StartDate AND @EndDate
            AND CallSubjectID BETWEEN 3 AND 99
            AND CallTypeID = 2 AND DeletedDate IS NULL
            AND c.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
        -- PARTICIPANT BEDNIGHTS:  Crisis and Resident Other = Emergency temporary shelter, use 518
        SELECT GrantorServiceID = 518, Contacts = ISNULL(SUM(CASE
            WHEN EntryDate = ExitDate THEN 1
            WHEN EntryDate >= @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, EntryDate, ExitDate)
            WHEN EntryDate < @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ExitDate)
            WHEN EntryDate >= @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, EntryDate, @EndDate) + 1
            WHEN EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            END), 0)
        FROM Intakes i
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate)
            AND ivt.VictimTypeID IS NOT NULL
            AND IntakeTypeID IN (1, 5) AND DeletedDate IS NULL
            AND ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        UNION ALL
        -- CHILD BEDNIGHTS:  Crisis and Resident Other = Emergency temporary shelter, use 518
        SELECT GrantorServiceID = 518, Contacts = ISNULL(SUM(CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.EntryDate >= @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, ci.EntryDate, ci.ExitDate)
            WHEN ci.EntryDate < @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ci.ExitDate)
            WHEN ci.EntryDate >= @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            END), 0)
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ivt.VictimTypeID IS NOT NULL
            AND i.IntakeTypeID IN (1, 5)
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        -- Dummy values of 0
        UNION ALL SELECT 501, 0
        UNION ALL SELECT 502, 0
        UNION ALL SELECT 503, 0
        UNION ALL SELECT 504, 0
        UNION ALL SELECT 505, 0
        UNION ALL SELECT 506, 0
        UNION ALL SELECT 507, 0
        UNION ALL SELECT 508, 0
        UNION ALL SELECT 509, 0
        UNION ALL SELECT 510, 0
        UNION ALL SELECT 511, 0
        UNION ALL SELECT 512, 0
        UNION ALL SELECT 513, 0
        UNION ALL SELECT 514, 0
        UNION ALL SELECT 515, 0
        UNION ALL SELECT 516, 0
        UNION ALL SELECT 517, 0
        UNION ALL SELECT 518, 0
        UNION ALL SELECT 519, 0
        ORDER BY GrantorServiceID;

    -- 'Other' Services provided, including the service name
        -- Participant victims
        SELECT s.ServiceID, ss.ServiceName, COUNT(cs.SessionID) AS Contacts
        FROM Intakes i INNER JOIN ClientSessions cs ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
            INNER JOIN ServiceFocus sf ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN Services ss ON sf.ServiceID = ss.ServiceID
            INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE sm.GrantorServiceID = 510 AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND i.DeletedDate IS NULL AND cs.DeletedDate is NULL AND s.DeletedDate IS NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        GROUP BY s.ServiceID, ServiceName
        UNION ALL
        -- Child victims
        SELECT ss.ServiceID, ss.ServiceName, COUNT(cs.SessionID) AS Contacts
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN ClientSessions cs ON ci.ChildIntakeID = cs.IntakeID AND cs.ClientTypeID = 2
            INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
            INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
            INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE sm.GrantorServiceID = 510 AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND i.DeletedDate IS NULL AND cs.DeletedDate is NULL AND s.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND i.ShelterID IN
            (SELECT gt.TargetID AS ShelterID
            FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID AND TargetTypeID = 1
            WHERE g.GrantorID = 5 AND g.GrantStart BETWEEN @StartDate AND @EndDate AND g.DeletedDate IS NULL)
        GROUP BY ss.ServiceID, ServiceName
		UNION ALL
		-- Community Client victims
		SELECT ss.ServiceID, ss.ServiceName, COUNT(cs.SessionID) AS Contacts
		FROM Communit
yMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID
			INNER JOIN Sessions s ON cs.SessionID = s.SessionID
			INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
			INNER JOIN ServiceFocus sf ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
			INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
		WHERE sm.GrantorServiceID = 510 AND s.SessionDate BETWEEN @StartDate AND @EndDate 
			AND cs.ClientTypeID = 4 AND cm.VictimTypeID > 2
			AND s.DeletedDate IS NULL AND cm.DeletedDate IS NULL AND cs.DeletedDate IS NULL
		GROUP BY ss.ServiceID, ss.ServiceName
		ORDER BY ServiceName;

    -- Organization data for the first page
        SELECT * FROM zShelterData;
            
    -- Results of Survey associated with the grant; ACJC GrantorID = 5
        SELECT SurveyName, q.GoalID, Goal, sq.QuestionID, Outcome, Response, qr.QuestionnaireID
        FROM Grants g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
            INNER JOIN Surveys s ON s.SurveyID = gs.SurveyID
            INNER JOIN SurveyQuestions sq ON s.SurveyID = sq.SurveyID
            INNER JOIN Questions q ON q.QuestionID = sq.QuestionID
            INNER JOIN QuestionResponses qr ON q.QuestionID = qr.QuestionID
            INNER JOIN Questionnaires qq ON qr.QuestionnaireID = qq.QuestionnaireID
            INNER JOIN Goals gg ON q.GoalID = gg.GoalID
        WHERE g.GrantorID = 5 AND g.GrantStart = @StartDate AND CompletedDate BETWEEN @StartDate AND @EndDate
            AND qq.DeletedDate IS NULL
        ORDER BY q.GoalID, sq.QuestionID;
       
    -- Volunteer Information, from Volunteer Activities and any volunteer service sessions
        SELECT s.StaffID, va.Hours
        FROM Staff s INNER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
            INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
        WHERE s.Status = 2 AND vs.ActivityDate BETWEEN @StartDate AND @EndDate
            AND vs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        UNION ALL
        SELECT s.StaffID, SessionHours
        FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
            INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        WHERE s.Status = 2 and sss.SessionDate BETWEEN @StartDate AND @EndDate
            AND sss.DeletedDate IS NULL AND s.DeletedDate IS NULL;

    -- Narrative Items
        SELECT Item, Narrative, Description = ''
        FROM ReportNarratives
        WHERE ReportNumber = @ReportNumber AND
        ReportDate = @StartDate AND DeletedDate IS NULL
        ORDER BY Item;

rpt_Assessments
CREATE PROCEDURE dbo.rpt_Assessments
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	SELECT i.IntakeID, p.LastName + ', ' + p.FirstName AS Participant, a.AssessmentDate,
        Income = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 1), 0),
        Employment = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 2), 0),
        Housing = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 3), 0),
        Food = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 4), 0),
        Childcare = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 5), 0),
        ChildEducation = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 6), 0),
        AdultEducation = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 7), 0),
        Legal = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 8), 0),
        HealthCare = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 9), 0),
        LifeSkills = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 10), 0),
        MentalHealth = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 11), 0),
        SubstanceAbuse = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 12), 0),
        FamilyRelations = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 13), 0),
        Mobility = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 14), 0),
        CommunityInvolvement = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 15), 0),
        Safety = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 16), 0),
        ParentingSkills = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 17), 0),
        CreditHistory = ISNULL((SELECT TOP 1 StatusID FROM AssessmentItems WHERE AssessmentID = a.AssessmentID AND DomainID = 18), 0)
    FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID 
        INNER JOIN Assessments a ON i.IntakeID = a.IntakeID
    WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
    ORDER BY i.IntakeID, a.AssessmentDate, a.AssessmentID;

rpt_BatteredImmigrantWomen
CREATE PROCEDURE dbo.rpt_BatteredImmigrantWomen
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
            -- Clients
                SELECT RTRIM(LastName + ', ' + FirstName + ' ' + MI) AS FullName, i.IntakeTypeID, x.IntakeType,
                    ISNULL(COUNT(ci.ChildID), 0) AS NumberChildren, Citizenship
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
                    INNER JOIN xCitizenship xc ON i.CitizenshipID = xc.CitizenshipID
                    LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
                WHERE i.CitizenshipID <> 2 AND
                    i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
                GROUP BY LastName, FirstName, MI, IntakeType, i.IntakeTypeID, Citizenship
                ORDER BY i.IntakeTypeID, Citizenship DESC, FullName;
            -- Referrals
                SELECT ClientTypeID = 1, i.IntakeTypeID, xi.IntakeType, xc.Citizenship, xr.ReferralType, SUM(r.NumberReferrals) AS Referrals
                FROM Referrals r INNER JOIN Intakes i ON r.IntakeID = i.IntakeID AND r.ClientTypeID = 1
                    INNER JOIN xReferralType xr ON r.ReferralTypeID = xr.ReferralTypeID 
                    INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
                    INNER JOIN xCitizenship xc ON i.CitizenshipID = xc.CitizenshipID
                WHERE i.CitizenshipID <> 2 AND
                    r.ReferralDate BETWEEN @StartDate AND @EndDate
                    AND r.DeletedDate IS NULL AND i.DeletedDate IS NULL
                GROUP BY ClientTypeID, i.IntakeTypeID, IntakeType, Citizenship, ReferralType
                UNION ALL
                SELECT ClientTypeID = 2, i.IntakeTypeID, xi.IntakeType, xc.Citizenship, xr.ReferralType, SUM(r.NumberReferrals) AS Referrals
                FROM Referrals r INNER JOIN ChildIntakes ci ON r.IntakeID = ci.ChildIntakeID AND r.ClientTypeID = 2
                    INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
                    INNER JOIN xReferralType xr ON r.ReferralTypeID = xr.ReferralTypeID
                    INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
                    INNER JOIN xCitizenship xc ON i.CitizenshipID = xc.CitizenshipID
                WHERE i.CitizenshipID <> 2 AND
                    r.ReferralDate BETWEEN @StartDate AND @EndDate
                    AND r.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
                GROUP BY ClientTypeID, i.IntakeTypeID, IntakeType, Citizenship, ReferralType
                ORDER BY i.IntakeTypeID, Citizenship DESC, ReferralType, ClientTypeID;
            -- Services
                SELECT ClientTypeID = 1, i.IntakeTypeID, IntakeType, Citizenship, s.SessionID, ServiceName,
                    SessionHours AS ClientHours, SessionHours = 0, NumberStaff
                FROM Sessions s INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
                    INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
                    INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
                    INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
                    INNER JOIN xCitizenship xc ON i.CitizenshipID = xc.CitizenshipID
                WHERE i.CitizenshipID <> 2 AND
                    s.SessionDate BETWEEN @StartDate AND @EndDate AND
                    i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
                UNION ALL
                SELECT ClientTypeID = 2, i.IntakeTypeID, IntakeType, Citizenship, s.SessionID, ServiceName,
                    SessionHours AS ClientHours, SessionHours = 0, NumberStaff
                FROM Sessions s INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
                    INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
                    INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
                    INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
                    INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
                    INNER JOIN xCitizenship xc ON i.CitizenshipID = xc.CitizenshipID
                WHERE i.CitizenshipID <> 2 AND
                    s.SessionDate BETWEEN @StartDate AND @EndDate AND
                    ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
                ORDER BY i.IntakeTypeID, Citizenship DESC, ServiceName, ClientTypeID, SessionID;

rpt_BedAssignments
CREATE PROCEDURE dbo.rpt_BedAssignments
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
    SELECT Campuses.CampusID, CampusName, ShelterName, RoomNumber AS Room, Beds.Description AS Bed, IntakeBeds.DateIn, Intakes.EntryDate,
    IntakeBeds.ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (P)' AS FullName, IntakeTypeID, Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    INNER JOIN  IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    INNER JOIN Intakes ON Intakes.IntakeID = IntakeBeds.IntakeID AND IntakeBeds.ClientTypeID = 1
    INNER JOIN Participants On Participants.ParticipantID = Intakes.ParticipantID
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And IntakeBeds.DeletedDate IS NULL And Intakes.DeletedDate IS NULL
    AND Participants.DeletedDate IS NULL AND Intakes.DeletedDate IS NULL
    UNION
    SELECT Campuses.CampusID, CampusName, ShelterName, RoomNumber AS Room, Beds.Description AS Bed, IntakeBeds.DateIn, ChildIntakes.EntryDate,
    IntakeBeds.ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (C)' AS FullName, IntakeTypeID, Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    INNER JOIN IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    INNER  JOIN ChildIntakes ON ChildIntakes.ChildIntakeID = IntakeBeds.IntakeID And IntakeBeds.ClientTypeID = 2
    INNER  JOIN Children ON ChildIntakes.ChildID = Children.ChildID
    INNER JOIN Intakes ON ChildIntakes.IntakeID = Intakes.IntakeID
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And IntakeBeds.DeletedDate IS NULL
    And Children.DeletedDate IS NULL And Intakes.DeletedDate IS NULL And ChildIntakes.DeletedDate IS NULL
        AND ChildIntakes.DeletedDate IS NULL
    UNION
    SELECT Campuses.CampusID, CampusName, ShelterName, RoomNumber AS Room, Beds.Description AS Bed, DateIn = NULL, EntryDate = NULL,
    ClientTypeID = 5, FullName = '', IntakeTypeID = 0, Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    LEFT OUTER JOIN IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    WHERE Beds.BedID NOT IN (SELECT BedID FROM IntakeBeds
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And DeletedDate IS NULL)
    ORDER BY CampusName, ShelterName, Room, Bed;

rpt_BedAssignments2
CREATE PROCEDURE dbo.rpt_BedAssignments2
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
    SELECT Campuses.CampusID, ShelterName, Rooms.RoomID, RoomNumber AS Room, Beds.Description AS Bed, IntakeBeds.DateIn, Intakes.EntryDate,
    IntakeBeds.ClientTypeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    INNER JOIN  IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    INNER JOIN Intakes ON Intakes.IntakeID = IntakeBeds.IntakeID AND IntakeBeds.ClientTypeID = 1
    INNER JOIN Participants On Participants.ParticipantID = Intakes.ParticipantID
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And IntakeBeds.DeletedDate IS NULL And Intakes.DeletedDate IS NULL
    UNION
    SELECT Campuses.CampusID, ShelterName, Rooms.RoomID, RoomNumber AS Room, Beds.Description AS Bed, IntakeBeds.DateIn, ChildIntakes.EntryDate,
    IntakeBeds.ClientTypeID, LastName + ', ' + FirstName + ' ' + MI AS FullName, Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    INNER JOIN IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    INNER  JOIN ChildIntakes ON ChildIntakes.ChildIntakeID = IntakeBeds.IntakeID And IntakeBeds.ClientTypeID = 2
    INNER  JOIN Children ON ChildIntakes.ChildID = Children.ChildID
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And IntakeBeds.DeletedDate IS NULL
        AND ChildIntakes.DeletedDate IS NULL
    UNION
    SELECT Campuses.CampusID, ShelterName, Rooms.RoomID, RoomNumber AS Room, Beds.Description AS Bed, DateIn = NULL, EntryDate = NULL,
    ClientTypeID = 5, FullName = 'Unoccupied', Shelters.ShelterID
    FROM Campuses INNER JOIN Shelters ON Campuses.CampusID = Shelters.CampusID
    INNER JOIN Rooms ON Shelters.ShelterID = Rooms.ShelterID
    INNER JOIN RoomBedAssignments ON Rooms.RoomID = RoomBedAssignments.RoomID
    INNER JOIN Beds ON RoomBedAssignments.BedID = Beds.BedID
    LEFT OUTER JOIN IntakeBeds ON Beds.BedID = IntakeBeds.BedID
    WHERE Beds.BedID NOT IN (SELECT BedID FROM IntakeBeds
    WHERE @StartDate >= IntakeBeds.DateIn And @StartDate < IsNull(IntakeBeds.DateOut, '6/6/2079') And DeletedDate IS NULL)
    ORDER BY CampusID, ShelterName, Room, ClientTypeID, Bed;

rpt_ClientSummary
-- Add IsHighRisk to columns retrieved for Client Summary report
CREATE PROCEDURE rpt_ClientSummary
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
    SELECT ShelterName, i.IntakeID, i.EntryDate, i.ExitDate, i.TANF_Eligible AS TANF, x.IntakeType, i.IntakeTypeID,
        p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ParticipantName, p.DOB,
        p.EthnicityID, Ethnicity, ISNULL(Tribe, '') AS Tribe, DATEDIFF(year, p.DOB, i.EntryDate) AS Age,
        p.OptionalIdentifier AS OptionalID, ci.ChildID, ci.ChildIntakeID, ci.EntryDate AS ChildEntry, ci.ExitDate AS ChildExit,
        c.DOB AS ChildDOB, DATEDIFF(year, c.DOB, ci.EntryDate) AS ChildAge, LOS = 0, ChildLOS = 0, ChildAges = '', NumberKids = 0,
        i.CountyID, i.LocationID, p.ReturnStatusID, i.ShelterID, i.IsHighRisk
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
                AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
        LEFT OUTER JOIN Children c ON ci.ChildID = c.ChildID
        LEFT OUTER JOIN TribalAffiliation ta ON p.ParticipantID = ta.ClientID AND ta.ClientTypeID = 1
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    ORDER BY ShelterName, ParticipantName, i.EntryDate, IntakeID;

rpt_CompareSurveys
CREATE PROCEDURE dbo.rpt_CompareSurveys
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @SurveyID INT)
	AS
	SELECT qq.Question, q.QuestionnaireID, qq.QuestionID, qr.Response, sq.QuestionNumber,
		qq.MaxRating, q.ControlNumber, p.LastName + ', ' + p.FirstName + ' (P)' AS Client,
		p.ParticipantID AS ClientID, q.CompletedDate
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN Questionnaires q ON i.IntakeID = q.IntakeID AND q.ClientTypeID = 1
		INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
		INNER JOIN Questions qq ON qq.QuestionID = qr.QuestionID
		INNER JOIN SurveyQuestions sq ON qq.QuestionID = sq.QuestionID
	WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
		AND q.SurveyID = @SurveyID
	UNION ALL
	SELECT qq.Question, q.QuestionnaireID, qq.QuestionID, qr.Response, sq.QuestionNumber,
		qq.MaxRating, q.ControlNumber, c.LastName + ', ' + c.FirstName + ' (C)' AS Client,
		c.ChildID AS ClientID, q.CompletedDate
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Questionnaires q ON ci.ChildIntakeID = q.IntakeID AND q.ClientTypeID = 2
		INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
		INNER JOIN Questions qq ON qq.QuestionID = qr.QuestionID
		INNER JOIN SurveyQuestions sq ON qq.QuestionID = sq.QuestionID
	UNION ALL
	SELECT qq.Question, q.QuestionnaireID, qq.QuestionID, qr.Response, sq.QuestionNumber,
		qq.MaxRating, q.ControlNumber, a.LastName + ', ' + a.FirstName + ' (A)' AS Client,
		a.AbuserID AS ClientID, q.CompletedDate
	FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
		INNER JOIN Questionnaires q ON ai.AbuserIntakeID = q.IntakeID AND q.ClientTypeID = 3
		INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
		INNER JOIN Questions qq ON qq.QuestionID = qr.QuestionID
		INNER JOIN SurveyQuestions sq ON qq.QuestionID = sq.QuestionID
	ORDER BY Client, q.CompletedDate, q.QuestionnaireID, qq.QuestionID

rpt_Demographics
CREATE PROCEDURE dbo.rpt_Demographics
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
    -- Demographic information on particpants and children
    SELECT s.ShelterName, s.ShelterID, p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName,
    p.OptionalIdentifier, p.Sex, p.DOB, DateDiff(year, p.DOB, i.EntryDate) AS Age, p.EthnicityID, ep.Ethnicity, tp.Tribe,
    i.IntakeID, i.IntakeTypeID, i.EntryDate, i.ExitDate, County, i.CountyID, Reservation, City, State, Location, i.LocationID,
    i.MentalIllness, i.PhysDisability, i.DevDisability, i.ChronicHealthCondition, i.Deaf, Disability = '',
    Religion, i.ReligionID, i.LanguageID, Language, i.IncomeEntry,
    IsNew = CAST(CASE WHEN i.EntryDate >= @StartDate THEN 1 ELSE 0 END AS BIT),
    c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ChildName, c.Sex AS ChildSex, c.DOB AS ChildDOB, c.ChildID,
    DateDiff(year, c.DOB, ci.EntryDate) AS ChildAge, c.EthnicityID AS ChildEthnicityID,
    ec.Ethnicity AS ChildEthnicity, tc.Tribe AS ChildTribe, ci.EntryDate AS ChildEntry, ci.ExitDate AS ChildExit,
    ci.MentalIllness AS ChildMentalIllness, ci.PhysDisability AS ChildPhysDisability, ci.DevDisability AS ChildDevDisability, ChildDisability = '',
    HouseholdSize = (SELECT COUNT(ChildID) FROM Children WHERE ParticipantID = p.ParticipantID) + 1
    FROM xTribe tp RIGHT OUTER JOIN TribalAffiliation tap ON tp.TribeID = tap.TribeID
    RIGHT OUTER JOIN Participants p ON p.ParticipantID = tap.ClientID And tap.ClientTypeID = 1
    INNER JOIN xEthnicity ep ON p.EthnicityID = ep.EthnicityID
    INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
    INNER JOIN xCounty ON xCounty.CountyID = i.CountyID
    INNER JOIN xReservation ON xReservation.ReservationID = i.ReservationID
    INNER JOIN xReligion ON xReligion.ReligionID = i.ReligionID
    INNER JOIN xLanguage ON xLanguage.LanguageID = i.LanguageID
    LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
    LEFT OUTER JOIN Children c ON ci.ChildID = c.ChildID AND c.DeletedDate IS NULL
    LEFT OUTER JOIN xEthnicity ec ON c.EthnicityID = ec.EthnicityID
    LEFT OUTER JOIN TribalAffiliation tac ON c.ChildID = tac.ClientID And tac.ClientTypeID = 2
    LEFT OUTER JOIN xTribe tc ON tac.TribeID = tc.TribeID
    LEFT OUTER JOIN xLocation ON i.LocationID = xLocation.LocationID
    WHERE i.DeletedDate IS NULL AND p.DeletedDate IS NULL And
    i.EntryDate <= @EndDate And (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    ORDER BY ShelterName, IntakeTypeID, FullName;
    -- Duplicated particpants during the report period
    SELECT LastName + ', ' + FirstName + ' ' + MI AS FullName FROM Participants
    WHERE DeletedDate IS NULL And ParticipantID IN
    (SELECT i.ParticipantID	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    WHERE p.DeletedDate IS NULL And i.DeletedDate IS NULL And
    i.EntryDate <= @EndDate And (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    GROUP BY i.ParticipantID HAVING COUNT(i.ParticipantID) > 1) 
	ORDER BY FullName;
    -- Duplicated children
    SELECT LastName + ', ' + FirstName + ' ' + MI AS FullName, ParticipantID
    FROM Children WHERE DeletedDate IS NULL And ChildID IN
    (SELECT c.ChildID FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
    WHERE c.DeletedDate IS NULL And
    ci.EntryDate <= @EndDate And (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
    GROUP BY c.ChildID HAVING COUNT(c.ChildID) > 1) 
	ORDER BY ParticipantID, FullName;

rpt_DesInterventionPerformanceMeasures
CREATE PROCEDURE dbo.rpt_DesInterventionPerformanceMeasures
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	DECLARE @GrantID INT, @PreviosQuarterStart SMALLDATETIME, @PreviousQuarterEnd SMALLDATETIME
	SET @PreviosQuarterStart = DATEADD(month, -3, @StartDate)
	SET @PreviousQuarterEnd = DATEADD(d, -1, DATEADD(m, DATEDIFF(m, 0, DATEADD(month, -1, @StartDate)) + 1, 0))

    SELECT TOP 1 @GrantID = GrantID
    FROM Grants
    WHERE DeletedDate IS NULL AND GrantorID = 2
        AND (@StartDate BETWEEN GrantStart AND GrantEnd
            OR @EndDate BETWEEN GrantStart ANd GrantEnd);

    -- Performance Measures
    -- Items 1 - 7, gets items for CURRENT clients
    -- Items 1 - 7 Participants (excluding Item 4
    SELECT i.ShelterID, i.IntakeTypeID, i.IntakeID, ClientTypeID = 1, i.ExitDate,
        i.IncomeIncreased AS Item1, i.EducationGoals AS Item2A, i.EducationImproved AS Item2B,
        i.HealthPlanGoals AS Item3A, i.HealthImproved AS Item3B,
        Item4A = CAST(0 AS BIT), Item4B = CAST(0 AS BIT),
        i.HasSafetyPlan AS Item5, i.AccessResources AS Item6, i.ServicesHelped AS Item7,
        Item8 = CAST(0 AS BIT), Item9 = CAST(0 AS BIT), Item10B = CAST(0 AS BIT),
        Item10C = CAST(0 AS BIT), CurrentParticipant = CAST(1 AS BIT),
        ExitedThisQuarter = CAST(0 AS BIT), ExitedLastQuarter = CAST(0 AS BIT)
    FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE i.EntryDate <= @EndDate
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Item 4 Children
    SELECT i.ShelterID, i.IntakeTypeID, ci.ChildIntakeID, ClientTypeID = 2, i.ExitDate,
        Item1 = CAST(0 AS BIT), Item2A = CAST(0 AS BIT), Item2B = CAST(0 AS BIT),
        Item3A = CAST(0 AS BIT), Item3B = CAST(0 AS BIT),
        ci.HealthPlanGoal AS Item4A, ci.HealthImproved AS Item4B,
        Item5 = CAST(0 AS BIT), Item6 = CAST(0 AS BIT), Item7 = CAST(0 AS BIT),
        Item8 = CAST(0 AS BIT), Item9 = CAST(0 AS BIT), Item10B = CAST(0 AS BIT), 
        Item10C = CAST(0 AS BIT), CurrentParticipant = CAST(0 AS BIT),
            ExitedThisQuarter = CAST(0 AS BIT), ExitedLastQuarter = CAST(0 AS BIT)
    FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE ci.EntryDate <= @EndDate
        AND (ci.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND ci.DeletedDate IS NULL AND c.DeletedDate IS NULL
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Item 8, 9 for Participants who exited during the period
    SELECT i.ShelterID, i.IntakeTypeID, i.IntakeID, ClientTypeID = 1, i.ExitDate,
        Item1 = CAST(0 AS BIT), Item2A = CAST(0 AS BIT), Item2B = CAST(0 AS BIT), 
        Item3A = CAST(0 AS BIT), Item3B = CAST(0 AS BIT), Item4A = CAST(0 AS BIT),
        Item4B = CAST(0 AS BIT), Item5 = CAST(0 AS BIT), Item6 = CAST(0 AS BIT), Item7 = CAST(0 AS BIT),
        i.EmployedAfterExit AS Item8, i.SafeHousing AS Item9,
        Item10B = CAST(0 AS BIT), Item10C = CAST(0 AS BIT), CurrentParticipant = CAST(0 AS BIT),
            ExitedThisQuarter = CAST(1 AS BIT), ExitedLastQuarter = CAST(0 AS BIT)
    FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Item 10 Participants exited last quarter, contacted
    SELECT i.ShelterID, i.IntakeTypeID, i.IntakeID, ClientTypeID = 1, i.ExitDate,
        Item1 = CAST(0 AS BIT), Item2A = CAST(0 AS BIT), Item2B = CAST(0 AS BIT),
        Item3A = CAST(0 AS BIT), Item3B = CAST(0 AS BIT), Item4A = CAST(0 AS BIT),
        Item4B = CAST(0 AS BIT), Item5 = CAST(0 AS BIT), Item6 = CAST(0 AS BIT), Item7 = CAST(0 AS BIT),
        Item8 = CAST(0 AS BIT), Item9 = CAST(0 AS BIT),
        i.ThreeMonthContact AS Item10B, i.ThreeMonthSafelyHoused AS Item10C, CurrentParticipant = CAST(0 AS BIT),
            ExitedThisQuarter = CAST(0 AS BIT), ExitedLastQuarter = CAST(1 AS BIT)
    FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE i.ExitDate BETWEEN @PreviosQuarterStart AND @PreviousQuarterEnd
        AND i.ThreeMonthContact = 1
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL;

    -- Narratives - Comments/Explanations
    -- Report narratives
        SELECT
        ContractNumber = ISNULL((SELECT TOP 1 ContractNumber FROM Grants WHERE GrantID = @GrantID), ''),
        Item1 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '1' AND DeletedDate IS NULL), ''),
        Item2 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '2' AND DeletedDate IS NULL), ''),
        Item3 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '3' AND DeletedDate IS NULL), ''),
        Item4 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '4' AND DeletedDate IS NULL), ''),
        Item5 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '5' AND DeletedDate IS NULL), ''),
        Item6 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '6' AND DeletedDate IS NULL), ''),
        Item7 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '7' AND DeletedDate IS NULL), ''),
        Item8 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '8' AND DeletedDate IS NULL), ''),
        Item9 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '9' AND DeletedDate IS NULL), ''),
        Item10 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '10' AND DeletedDate IS NULL), ''),
        SubmittedBy = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Contact' AND DeletedDate IS NULL), ''),
        Phone = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Phone' AND DeletedDate IS NULL), '');

rpt_DESoutcomes
CREATE PROCEDURE dbo.rpt_DESoutcomes
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT qr.QuestionnaireID, qr.QuestionID, qr.Response
    FROM Grants g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
        INNER JOIN Surveys s ON s.SurveyID = gs.SurveyID
        INNER JOIN Questionnaires q ON s.SurveyID = q.SurveyID
        INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
    WHERE g.GrantorID = 2 
        AND ((@StartDate BETWEEN g.GrantStart AND g.GrantEnd)
            OR (@EndDate BETWEEN g.GrantStart AND g.GrantEnd))
        AND qr.QuestionID IN (1, 8, 9)
        AND q.CompletedDate BETWEEN @StartDate AND @EndDate
        AND g.DeletedDate IS NULL AND q.DeletedDate IS NULL
        AND s.DeletedDate IS NULL;

rpt_DirectorsReport
CREATE PROCEDURE dbo.rpt_DirectorsReport
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Participants
    SELECT CampusName, ShelterName, ClientTypeID = 1,
        New = CASE WHEN i.EntryDate >= @StartDate THEN 1 ELSE 0 END,
        Bednights = CASE
        WHEN i.EntryDate = i.ExitDate THEN 1
        WHEN i.EntryDate BETWEEN @StartDate AND @EndDate THEN CASE
            WHEN i.ExitDate IS NULL OR i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END
        WHEN i.ExitDate IS NULL OR i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
        ELSE DATEDIFF(day, @StartDate, i.ExitDate) END
    FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
    WHERE i.DeletedDate IS NULL AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    UNION ALL
    -- Children
    SELECT CampusName, ShelterName, ClientTypeID = 2,
        New = CASE WHEN ci.EntryDate >= @StartDate THEN 1 ELSE 0 END,
        Bednights = CASE
        WHEN ci.EntryDate = ci.ExitDate THEN 1
        WHEN ci.EntryDate BETWEEN @StartDate AND @EndDate THEN CASE
            WHEN ci.ExitDate IS NULL OR ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDAte, @EndDate) + 1
            ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END
        WHEN ci.ExitDate IS NULL OR ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
        ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END 
    FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
    ORDER BY CampusName, ShelterName, New, ClientTypeID;
    -- Ethnicity for all crisis/transitional clients/children
    -- Get all ethnicities
    SELECT Ethnicity, EthnicityID, Participant = 0, Child = 0 FROM xEthnicity WHERE EthnicityID <= 100
    UNION ALL
    -- Participants with listed ethnicity
    SELECT x.Ethnicity, p.EthnicityID, Participant = 1, Child = 0
    FROM xEthnicity x INNER JOIN Participants p ON x.EthnicityID = p.EthnicityID
    INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    WHERE p.DeletedDate IS NULL And i.DeletedDate IS NULL And IntakeTypeID IN (1, 2, 3, 5)
    And i.EntryDate <= @EndDate And (i.ExitDate IS NULL Or i.ExitDate >= @StartDate) And x.EthnicityID < 100
    UNION ALL
    -- Participants with 'Other' ethnicity
    SELECT Ethnicity = 'Other', EthnicityID = 100, Participant = 1, Child = 0
    FROM xEthnicity x INNER JOIN Participants p ON x.EthnicityID = p.EthnicityID
    INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    WHERE p.DeletedDate IS NULL And i.DeletedDate IS NULL And IntakeTypeID IN (1, 2, 3, 5)
    And i.EntryDate <= @EndDate And (i.ExitDate IS NULL Or i.ExitDate >= @StartDate) And x.EthnicityID >= 100
    UNION ALL
    -- Children with listed ethnicity
    SELECT x.Ethnicity, c.EthnicityID, Participant = 0, Child = 1 FROM xEthnicity x INNER JOIN Children c ON c.EthnicityID = x.EthnicityID
    INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
    WHERE c.DeletedDate IS NULL And ci.DeletedDate IS NULL And i.DeletedDate IS NULL
    And i.IntakeTypeID IN (1, 2, 3, 5) And ci.EntryDate <= @EndDate And
    (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate) And x.EthnicityID < 100
    UNION ALL
    -- Children with 'Other' ethnicity
    SELECT Ethnicity = 'Other', EthnicityID = 100, Participant = 0, Child = 1
    FROM xEthnicity x INNER JOIN Children c ON c.EthnicityID = x.EthnicityID
    INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
    WHERE c.DeletedDate IS NULL And ci.DeletedDate IS NULL And i.DeletedDate IS NULL
    And i.IntakeTypeID IN (1, 2, 3, 5) And ci.EntryDate <= @EndDate And
    (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate) And x.EthnicityID >= 100
    ORDER BY EthnicityID, Participant DESC;
	-- Income Over/Under 25000 Annual
	SELECT Over25 = CASE When (IncomeEntry * 12) >= 25000 Then 1 Else 0 END,
	Unknown = CASE When IncomeEntry IS NULL Then 1 Else 0 END,
	Under25 = CASE When (IncomeEntry * 12) < 25000 Then 1 Else 0 END
	FROM Intakes WHERE DeletedDate IS NULL And IntakeTypeID IN (1, 2, 3, 5)
	And EntryDate <= @EndDate And (ExitDate IS NULL OR ExitDate >= @StartDate);
	-- DOB (Age)
	SELECT DOB, i.EntryDate, DateDiff(year, DOB, EntryDate) As Age, ClientTypeID = 1
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
	WHERE p.DeletedDate IS NULL And i.DeletedDate IS NULL And i.IntakeTypeID IN (1, 2, 3, 5)
	And i.EntryDate <= @EndDate And (i.ExitDate IS NULL Or i.ExitDate >= @StartDate)
	UNION ALL SELECT DOB, ci.EntryDate, DateDiff(year, DOB, ci.EntryDate) As Age, ClientTypeID = 2
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
	WHERE c.DeletedDate IS NULL And ci.DeletedDate IS NULL And i.DeletedDate IS NULL And i.IntakeTypeID In (1, 2, 3, 5)
	And ci.EntryDate <= @EndDate And (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate)
	ORDER BY ClientTypeID, DOB DESC;
	-- Length of stay for exits during period
	SELECT CampusName, ShelterName, LengthOfStay = CASE WHEN EntryDate = ExitDate THEN 1
	ELSE DateDiff(day, EntryDate, ExitDate) END FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
	INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
	WHERE i.DeletedDate IS NULL And ExitDate BETWEEN @StartDate And @EndDate And IntakeTypeID IN (1, 2, 3, 5)
	ORDER BY CampusName, ShelterName;
	-- Exit Employment
	SELECT EmploymentExitID, Employment, Counter = 1, CampusName, ShelterName
	FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
	INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
	INNER JOIN xEmployment x ON i.EmploymentExitID = x.EmploymentID
	WHERE i.DeletedDate IS NULL And EmploymentExitID < 7 And ExitDate BETWEEN @StartDate And @EndDate And i.IntakeTypeID IN (1, 2, 3, 5)
	UNION ALL
	SELECT  EmploymentExitID = 100, Employment = '--Not in work force--', Counter = 1, CampusName, ShelterName
	FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
	INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
	INNER JOIN xEmployment x ON i.EmploymentExitID = x.EmploymentID
	WHERE i.DeletedDate IS NULL And EmploymentExitID > 6 And ExitDate BETWEEN @StartDate And @EndDate And i.IntakeTypeID IN (1, 2, 3, 5)
	ORDER BY CampusName, ShelterName, EmploymentExitID;   
	-- Exit Destination
	SELECT CampusName, ShelterName, ExitDestination, i.ExitDestinationID, Counter = 1
	FROM Campuses c INNER JOIN Shelters s ON c.CampusID = s.CampusID
	INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
	INNER JOIN xExitDestination x ON i.ExitDestinationID = x.ExitDestinationID
	WHERE i.DeletedDate IS NULL And ExitDate BETWEEN @StartDate And @EndDate And i.IntakeTypeID IN (1, 2, 3, 5)
	ORDER BY CampusName, ShelterName, ExitDestinationID;
	-- Hotline Summary
	SELECT c.ShelterID, ShelterName, CallTypeID, NumberChildren, CallSubjectID, RequestOutcomeID
	FROM Shelters s INNER JOIN Calls c ON s.ShelterID = c.ShelterID
	LEFT OUTER JOIN ShelterRequests sr ON c.CallID = sr.CallID
	WHERE CallDate BETWEEN @StartDate AND @EndDate AND c.DeletedDate IS NULL AND CallTypeID < 4
	ORDER BY ShelterID;

rpt_DVLAP
CREATE PROCEDURE rpt_DVLAP
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    DECLARE @GrantStart SMALLDATETIME, @GrantEnd SMALLDATETIME, @GrantID INT
    SELECT TOP 1 @GrantID = GrantID, @GrantStart = GrantStart, @GrantEnd = GrantEnd 
    FROM Grants WHERE GrantorID = 6 AND @StartDate BETWEEN GrantStart AND GrantEnd;

    -- All Clients
        SELECT p.ParticipantID, FullName = p.LastName + ', ' + p.FirstName,
            i.TANF_Eligible, p.Sex, p.EthnicityID, i.CountyID, p.DOB, Age = DATEDIFF(year, p.DOB, i.EntryDate),
            GrantorServiceID, PreviousQuarter = CAST(CASE WHEN SessionDate < @StartDate THEN 1 ELSE 0 END AS BIT),
            s.SessionDate, i.EntryDate
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        	INNER JOIN Sessions s ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
        	INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        	INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
        	INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        WHERE sm.GrantorID = 6 AND s.SessionDate BETWEEN @GrantStart AND @EndDate
        	AND cs.ClientTypeID = 1
        	AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        ORDER BY p.ParticipantID, SessionDate;

    -- Services
        SELECT p.ParticipantID, FullName = p.LastName + ', ' + p.FirstName,
            sm.GrantorServiceID, gs.GrantorService, ss.ServiceName, s.SessionDate
        FROM GrantorServices gs INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        WHERE sm.GrantorID = 6 AND s.SessionDate BETWEEN @GrantStart AND @EndDate AND cs.ClientTypeID = 1
            AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
            --AND p.ParticipantID NOT IN (
            --    SELECT p1.ParticipantID
            --    FROM Participants p1 INNER JOIN Intakes i1 ON p1.ParticipantID = i1.ParticipantID
            --        INNER JOIN ClientSessions cs1 ON i1.IntakeID = cs1.IntakeID
            --        INNER JOIN Sessions s1 ON cs1.SessionID = s1.SessionID
            --        INNER JOIN ServiceFocus sf1 ON s1.ServiceID = sf1.ServiceID AND s1.FocusID = sf1.FocusID
            --        INNER JOIN ServiceMap sm1 ON sf1.ServiceFocusID = sm1.ServiceFocusID
            --    WHERE sm1.GrantorID = 6 AND s1.SessionDate BETWEEN @GrantStart AND DATEADD(day, -1, @StartDate)
            --        AND p1.DeletedDate IS NULL AND cs1.DeletedDate IS NULL AND s1.DeletedDate IS NULL
            --        AND sm.GrantorServiceID = sm1.GrantorServiceID
            --        AND cs.ClientTypeID = 1)
        ORDER BY FullName, p.ParticipantID, sm.GrantorServiceID, s.SessionDate;
 
    -- Presentations
        SELECT p.PresentationID, p.PresentationDate, x.Topic, NumberAttended, Location
        FROM Presentations p INNER JOIN PresentationTopics pt ON p.PresentationID = pt.PresentationID
            INNER JOIN xTopic x ON pt.TopicID = x.TopicID
        WHERE p.DeletedDate IS NULL AND IsPresentation = 1 AND PresentationDate BETWEEN @StartDate AND @EndDate
        ORDER BY PresentationDate, Topic;


rpt_DVLAPinvoice
CREATE PROCEDURE dbo.rpt_DVLAPinvoice
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT TOP 1 ISNULL(ContractNumber, '') AS ContractNumber
    FROM Grants
    WHERE GrantorID = 6
        AND @StartDate BETWEEN GrantStart AND GrantEnd
        AND DeletedDate IS NULL;
    SELECT s.SessionHours, ss.ServiceName, f.Focus, s.SessionDate, p.LastName + ', ' + p.FirstName AS Participant
    FROM GrantorServices gs INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
        INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
        INNER JOIN Focus f ON s.FocusID = f.FocusID 
    WHERE sm.GrantorID = 6 AND s.SessionDate BETWEEN @StartDate AND @EndDate AND cs.ClientTypeID = 1
        AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND i.TANF_Eligible = 1
    ORDER BY Participant, SessionDate;

rpt_DVSR
CREATE PROCEDURE rpt_DVSR
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	DECLARE @GrantID INT;
	-- Grant for this report
		SELECT TOP 1 @GrantID = GrantID
		FROM Grants
		WHERE DeletedDate IS NULL AND GrantorID = 2
			AND (@StartDate BETWEEN GrantStart AND GrantEnd
				OR @EndDate BETWEEN GrantStart ANd GrantEnd);

	-- Item 2 Contract Number
		SELECT TOP 1 ContractNumber
		FROM Grants
		WHERE GrantID = @GrantID;

	-- Item 5A Counties Served
		SELECT x.CountyID, COUNT(i.CountyID) AS NumberServed
		FROM xCounty x INNER JOIN Intakes i ON x.CountyID = i.CountyID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.DeletedDate IS NULL AND i.CountyID BETWEEN 2 AND 16
			AND EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate)
			AND i.IntakeTypeID <> 5
			AND gt.GrantID = @GrantID
		GROUP BY x.CountyID;

	-- Item 5B Reservations Served
		SELECT x.ReservationID, COUNT(i.ReservationID) AS NumberServed
		FROM xReservation x INNER JOIN Intakes i ON x.ReservationID = i.ReservationID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.DeletedDate IS NULL AND i.ReservationID BETWEEN 2 AND 21
			AND EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate)
			AND i.IntakeTypeID <> 5
			AND gt.GrantID = @GrantID
		GROUP BY x.ReservationID;
	-- Item 6 Program Staff
		SELECT Status, COUNT(s.StaffID) AS NumberStaff, Hours = 0
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID 
		WHERE (se.HireDate IS NULL Or se.HireDate <= @EndDate)
			And (s.DateLeft IS NULL Or s.DateLeft > @EndDate )
			And s.DeletedDate IS NULL And Status BETWEEN 0 And 1
		GROUP BY Status
		UNION ALL
		SELECT Status, COUNT(s.StaffID) AS NumberStaff, Hours =
			((SELECT ISNULL(SUM(va.Hours), 0)
			FROM VolunteerActivity va INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
			WHERE vs.DeletedDate IS NULL And ActivityDate BETWEEN @StartDate AND @EndDate)
			+
			(SELECT ISNULL(SUM(SessionHours), 0) FROM Sessions s INNER JOIN StaffSessions ss
			ON s.SessionID = ss.SessionID INNER JOIN Staff ON ss.StaffID = Staff.StaffID WHERE
			Staff.Status = 2 And s.DeletedDate IS NULL And Staff.DeletedDate IS NULL
				And SessionDate BETWEEN @StartDate AND @EndDate))
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
		WHERE (se.HireDate IS NULL Or se.HireDate <= @EndDate)
			And (s.DateLeft IS NULL Or s.DateLeft > @EndDate )
			And s.DeletedDate IS NULL And Status = 2
		GROUP BY Status
		UNION ALL
		SELECT Status = 2, OneTimeVolunteers, OneTimeHours * OneTimeVolunteers
		FROM VolunteerActivities
		WHERE DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate
		UNION ALL SELECT Status = 0, NumberStaff = 0, Hours = 0
		UNION ALL SELECT Status = 1, NumberStaff = 0, Hours = 0
		UNION ALL SELECT Status = 2, NumberStaff = 0, Hours = 0
		-- Block added to SUBTRACT volunteers on staff who had no activities or service sessions
		-- during the report period
		UNION ALL
		SELECT s.Status, -1 * COUNT(s.StaffID) AS NumberStaff, Hours = 0
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
			LEFT OUTER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
			LEFT OUTER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
		WHERE s.Status = 2 And s.DeletedDate IS NULL AND
			(se.HireDate IS NULL Or se.HireDate <= @EndDate) AND
			(s.DateLeft IS NULL Or s.DateLeft > @EndDate ) AND
			(ss.StaffID IS NULL AND va.StaffID IS NULL)
		GROUP BY Status
		ORDER BY Status;

	-- Item 7 Capacity
		SELECT HousingTypeID = 1, ISNULL(COUNT(b.BedID), 0) AS Beds
		FROM Shelters s INNER JOIN Beds b ON s.ShelterID = b.ShelterID AND s.HousingTypeID = 1
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE gt.GrantID = @GrantID AND s.IsCurrent = 1 AND b.IsCrib = 0 AND s.ShelterTypeID = 1
			AND b.DeletedDate IS NULL AND s.DeletedDate IS NULL
			AND b.ServiceStart <= @EndDate AND (b.ServiceEnd IS NULL OR b.ServiceEnd >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 2, COUNT(i.IntakeID) AS Beds
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 2
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE gt.GrantID = @GrantID AND s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 2, COUNT(ci.IntakeID) AS Beds
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 2
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE gt.GrantID = @GrantID AND s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 3, COUNT(i.IntakeID) AS Beds
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 3
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE gt.GrantID = @GrantID AND s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 3, COUNT(ci.IntakeID) AS Beds
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 3
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE  gt.GrantID = @GrantID AND s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 4, COUNT(r.RoomID)
		FROM Shelters s INNER JOIN Rooms r ON s.ShelterID = r.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE gt.GrantID = @GrantID AND s.IsCurrent = 1 AND s.ShelterTypeID = 2
			AND r.DeletedDate IS NULL AND s.DeletedDate IS NULL
			AND r.ServiceStart <= @EndDate AND (r.ServiceEnd IS NULL OR r.ServiceEnd >= @StartDate);

	-- Item 8 Requests for Shelter due to Domestic Violence
		SELECT COUNT(c.CallID) AS Requests, SUM(c.NumberChildren) AS Children
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
		WHERE c.CallSubjectID = 5 AND c.DeletedDate IS NULL
			AND c.CallDate BETWEEN @StartDate AND @EndDate;

	-- Item 9 Reasons Shelter Not Provided
		SELECT c.CallID, c.NumberChildren, x.ReasonDenied, ReasonID = CASE
			WHEN sr.RequestOutcomeID = 7 THEN 100
			ELSE sr.ReasonDeniedID END
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID AND c.DeletedDate IS NULL
			INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
				AND c.CallSubjectID = 5 AND RequestOutcomeID IN (1, 7)
		ORDER BY ReasonID;

	-- Item 9 Other Reasons Shelter Denied -- Other
		SELECT x.ReasonDenied + ' (' + CAST(COUNT(x.ReasonDeniedID) AS VARCHAR) + ')' AS ReasonDenied
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID AND c.DeletedDate IS NULL
			INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND CallSubjectID = 5 AND RequestOutcomeID IN (1, 7)
			AND (sr.ReasonDeniedID IN (2, 6, 9, 10) OR sr.ReasonDeniedID > 100)
		GROUP BY x.ReasonDenied ORDER BY x.ReasonDenied;

	-- Item 10 and 11 Shelter:  Bednights
		-- NEW CRISIS/HOMELESS CLIENTS
		-- Crisis/Homeless Women
		SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
 s.HousingTypeID, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'F' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Crisis/Homeless Men
		SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, s.HousingTypeID, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'M' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Crisis/Homeless Children
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, s.HousingTypeID, Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END, NewClient = 1
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Child absences during period, i.e., negative bednights
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, s.HousingTypeID, Bednights = CASE
			WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
			WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 1
		FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.DeletedDate IS NULL
			AND ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ca.DateOut BETWEEN @StartDate AND @EndDate
			AND gt.GrantID = @GrantID
		UNION ALL
		-- CARRYOVER CRISIS/HOMELESS CLIENTS
		---- Women Crisis/Homeless
		SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, s.HousingTypeID, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'F' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		---- Men Crisis/Homeless
		SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, s.HousingTypeID, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'M' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		---- Children Crisis/Homeless
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, s.HousingTypeID, Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END, NewClient = 0
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Child Absences Crisis/Homeless (Carryover)
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, s.HousingTypeID, Bednights = CASE
			WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
			WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 0
		FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE  ci.DeletedDate IS NULL
			AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND ca.DateOut <= @EndDate
			AND (ca.DateReturn IS NULL OR ca.DateReturn > @StartDate)
			AND i.IntakeTypeID IN (1, 3)
			AND gt.GrantID = @GrantID
		UNION ALL
		-- New Transitional Clients
		-- Tran'l Women
		SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, HousingTypeID = 4, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID = 2 AND p.Sex = 'F' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- New Tran'l Men
		SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, HousingTypeID = 4, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1

			ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID = 2 AND p.Sex = 'M' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- New Tran'l Children
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END, NewClient = 1
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID = 2 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID		
		UNION ALL
		-- Tran'l Child absences (new)
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
			WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
			WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 1
		FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.DeletedDate IS NULL
			AND ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID = 2 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ca.DateOut BETWEEN @StartDate AND @EndDate
			AND gt.GrantID = @GrantID
		UNION ALL
		-- CARRYOVER Tran'l Clients
		-- Tran'l Women
		SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, HousingTypeID = 4, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.IntakeTypeID = 2 AND p.Sex = 'F' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Tran'l Men
		SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, HousingTypeID = 4, Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.IntakeTypeID = 2 AND p.Sex = 'M' AND p.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Tran'l Children
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END, NewClient = 0
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND i.IntakeTypeID = 2 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Child Absences, Tran'l Carryover
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
			WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
			WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
			ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 0
		FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE  ci.DeletedDate IS NULL
			AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND ca.DateOut <= @EndDate
			AND (ca.DateReturn IS NULL OR ca.DateReturn > @StartDate)
			AND i.IntakeTypeID = 2
			AND gt.GrantID = @GrantID
		-- Dummy rows for each type of intake for New clients
		UNION ALL SELECT 0, 0, 0, 1, 0, 1
		UNION ALL SELECT 0, 0, 0, 2, 0, 1
		UNION ALL SELECT 0, 0, 0, 3, 0, 1
		UNION ALL SELECT 0, 0, 0, 4, 0, 1
		-- Dummy rows for each type of intake for Carryover clients
		UNION ALL SELECT 0, 0, 0, 1, 0, 0
		UNION ALL SELECT 0, 0, 0, 2, 0, 0
		UNION ALL SELECT 0, 0, 0, 3, 0, 0
		UNION ALL SELECT 0, 0, 0, 4, 0, 0
		ORDER BY NewClient DESC, HousingTypeID;

	-- Item 10 and 11 Services
		-- ALL Crisis/Homeless/Transitional/Non-Res DV/Non-Res Other Women
		SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
			i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff,
			NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
			NewClient = CASE WHEN i.EntryDate < @StartDate THEN 0 ELSE 1 END
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
			INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND sm.GrantorServiceID IN (201, 202, 203, 205)
			AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND i.IntakeTypeID <> 5 AND p.Sex = 'F'
			AND gt.GrantID = @GrantID
		UNION ALL
		-- ALL Crisis/Homeless/Non-Res DV/ Non-Res Other Men
		SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0,
			i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff,
			NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
			NewClient = CASE WHEN i.EntryDate < @StartDate THEN 0 ELSE 1 END
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND 
s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
			INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND sm.GrantorServiceID IN (201, 202, 203, 205)
			AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND i.IntakeTypeID <> 5 AND p.Sex = 'M'
			AND gt.GrantID = @GrantID
		UNION ALL
		-- ALL Crisis/Homeless/Non-Res DV/Non-Res Other Children
		SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID,
			i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff,
			NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
			NewClient = CASE WHEN ci.EntryDate < @StartDate THEN 0 ELSE 1 END
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND sm.GrantorServiceID IN (201, 202, 203, 205)
			AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND i.IntakeTypeID <> 5
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Community Clients have no intake; label them as Non-Res DV (IntakeTypeID = 4) and not New,
		-- so they all appear in Item 11 non-residents.  Add 1000000 to their WomanID/ManID so they will
		-- be distinct from clients with intakes

		-- Community Client Women
		SELECT WomanID = cm.MemberID + 1000000, ManID = 0, ChildID = 0,
			IntakeTypeID = 4, sm.GrantorServiceID, s.SessionHours, s.NumberStaff,
			NumberInGroup =
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
			NewClient = 0
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorServiceID IN (201, 202, 203, 205)
			AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND cm.Sex = 'F'
		UNION ALL

		-- Community Client Men
		SELECT WomanID = 0, ManID = cm.MemberID + 1000000, ChildID = 0,
			IntakeTypeID = 4, sm.GrantorServiceID, s.SessionHours, s.NumberStaff,
			NumberInGroup =
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
			NewClient = 0
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorServiceID IN (201, 202, 203, 205)
			AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
			AND cm.Sex = 'M'


		-- Dummy rows to ensure entries even when a service was not provided during report period
		-- for all intake types, new and carryover clients
		-- WomanID/ManID/ChildID/IntakeTypeID, GrantorServiceID, SessionHours, NumberStaff, NumberInGroup, NewClient 

		-- New Residential clients
		UNION ALL SELECT 0, 0, 0, 1, 201, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 1, 202, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 1, 203, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 1, 205, 0.0, 0, 0, 1
		-- New NonResidential clients
		UNION ALL SELECT 0, 0, 0, 4, 201, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 4, 202, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 4, 203, 0.0, 0, 0, 1
		UNION ALL SELECT 0, 0, 0, 4, 205, 0.0, 0, 0, 1
		-- Carryover Residential clients
		UNION ALL SELECT 0, 0, 0, 1, 201, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 1, 202, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 1, 203, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 1, 205, 0.0, 0, 0, 0
		-- Carryover NonResidential clients
		UNION ALL SELECT 0, 0, 0, 4, 201, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 4, 202, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 4, 203, 0.0, 0, 0, 0
		UNION ALL SELECT 0, 0, 0, 4, 205, 0.0, 0, 0, 0
		ORDER BY NewClient DESC, GrantorServiceID; 

	-- Item 10 Transportation for NEW clients
		-- Crisis, Homeless, Transitional, NonRes DV, and NonRes Other Participants
		SELECT GrantorServiceID, s.SessionID, NumberStaff, i.IntakeTypeID, s.SessionHours
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1
			INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND sm.GrantorServiceID IN (206, 207)
			AND s.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION
		SELECT GrantorServiceID, s.SessionID, NumberStaff, i.IntakeTypeID, s.SessionHours
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2
			INNER JOIN ChildIntakes ci ON ci.ChildIntakeID = cs.IntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
			AND ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND sm.GrantorServiceID IN (206, 207)
			AND s.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL SELECT 206, 0, 0, 1, 0.0
		UNION ALL SELECT 207, 0, 0, 1, 0.0
		UNION ALL SELECT 206, 0, 0, 4, 0.0
		UNION ALL SELECT 207, 0, 0, 4, 0.0
		ORDER BY GrantorServiceID;

	-- Item 11 Transportation for clients entering in a previous quarter
		-- Transportation f
		SELECT sm.GrantorServiceID, s.SessionID, NumberStaff, i.IntakeTypeID, s.SessionHours
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1
			INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
				INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND s.SessionDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND sm.GrantorServiceID IN (206, 207)
			AND s.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION
		SELECT sm.GrantorServiceID, s.SessionID, NumberStaff, i.IntakeTypeID, s.SessionHours
		FROM ServiceMap sm I
NNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2
			INNER JOIN ChildIntakes ci ON ci.ChildIntakeID = cs.IntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
				INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND s.SessionDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND sm.GrantorServiceID IN (206, 207)
			AND s.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION SELECT 206, 0, 0, 1, 0.0
		UNION SELECT 207, 0, 0, 1, 0.0
		UNION SELECT 206, 0, 0, 4, 0.0
		UNION SELECT 207, 0, 0, 4, 0.0
		ORDER BY GrantorServiceID; 

	-- Item 12 Referrals for Primary Clients, Residential and Non-Residential
		SELECT DISTINCT r.ClientID, r.ReferralTypeID, Resident = CASE
			WHEN i.IntakeTypeID < 4 THEN 1
			ELSE 0 END
		FROM Referrals r INNER JOIN Intakes i ON r.IntakeID = i.IntakeID AND r.ClientTypeID = 1
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate 
			AND r.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND i.IntakeTypeID <> 5
			AND gt.GrantID = @GrantID
		-- Add Community Member referrals; increment ClientID by 1000000 to ensure distinct values
		UNION ALL
		SELECT DISTINCT r.ClientID + 1000000 AS ClientID, r.ReferralTypeID, Resident = 0
		FROM Referrals r INNER JOIN CommunityMembers cm ON r.ClientID = cm.MemberID AND r.ClientTypeID = 4
		WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
			AND r.DeletedDate IS NULL AND cm.DeletedDate IS NULL
		ORDER BY ReferralTypeID; 

	-- Item 12 Other Referrals
		SELECT x.ReferralType --+ ' (' + CAST(COUNT(r.ReferralTypeID) AS VARCHAR) + ')' AS ReferralType
		FROM Referrals r INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
			INNER JOIN Intakes i ON r.IntakeID = i.IntakeID AND r.ClientTypeID = 1
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
			AND r.DeletedDate IS NULL AND r.ReferralTypeID > 100
			AND i.IntakeTypeID <> 5
			AND gt.GrantID = @GrantID
		GROUP BY x.ReferralType
		ORDER BY x.ReferralType;

	-- Item 13 Demographics of NEW clients
		-- Primary Clients
		SELECT ClientTypeID = 1, p.ParticipantID AS ClientID, Age = 0, p.DOB, p.Sex, p.EthnicityID, i.TANF_Eligible,
			IncomeEntry = CASE WHEN i.IncomeEntry IS NULL THEN NULL ELSE 12 * i.IncomeEntry END,
			CashAssistance = CAST(CASE WHEN TANF = 1 OR CashAssistance = 1 THEN 1 ELSE 0 END AS BIT), i.WIC, i.LowIncomeHousing, i.SSI, i.SSDI, i.KidsCare, i.FoodStamps,
			AHCCCS = CAST(CASE WHEN AHCCCS = 1 OR Medicaid = 1 THEN 1 ELSE 0 END AS BIT), i.VetBenefits, i.UnemploymentBenefits, i.EntryDate
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION ALL
		-- Children
		SELECT ClientTypeID = 2, c.ChildID AS ClientID, Age = 0, c.DOB, c.Sex, c.EthnicityID, i.TANF_Eligible,
			NULL,
			CashAssistance = CAST(CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN 1 ELSE 0 END AS BIT), ci.WIC, ci.LowIncomeHousing, ci.SSI, ci.SSDI, ci.KidsCare, ci.FoodStamps,
			ci.AHCCCS, i.VetBenefits, i.UnemploymentBenefits, ci.EntryDate
		FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		ORDER BY ClientTypeID, ClientID, EntryDate;

	-- Item 13 Other Ethnicities
		SELECT ClientTypeID = 1, p.ParticipantID AS ClientID, p.EthnicityID, Ethnicity
		FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
			INNER JOIN xEthnicity x ON p.EthnicityID = x.EthnicityID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND (p.EthnicityID IN (1, 6, 8) OR p.EthnicityID > 100)
			AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		UNION
		SELECT ClientTypeID = 2, c.ChildID AS ClientID,  c.EthnicityID, Ethnicity
		FROM ChildIntakes ci INNER JOIN Children c ON ci.ChildID = c.ChildID
			INNER JOIN xEthnicity x ON c.EthnicityID = x.EthnicityID
			INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID <> 5
			AND (c.EthnicityID IN (1, 6, 8) OR c.EthnicityID > 100)
			AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		ORDER BY EthnicityID;

	-- Item 14 and 15 Length-of-Stay and Destination of Clients who exited
		SELECT DATEDIFF(day, i.EntryDate, i.ExitDate) AS Bednights, ISNULL(i.ExitDestinationID, 8) AS ExitDestinationID,
			HousingTypeID = CASE WHEN i.IntakeTypeID = 2 THEN 4 ELSE s.HousingTypeID END,
			Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID)
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 2, 3)
			AND gt.GrantID = @GrantID
			AND i.DeletedDate IS NULL; 

	-- Item 15 Other Exit Destinations
		SELECT x.ExitDestination + ' (' + CAST(COUNT(x.ExitDestination) AS VARCHAR) + ')' AS ExitDestination
		FROM Intakes i INNER JOIN xExitDestination x ON i.ExitDestinationID = x.ExitDestinationID
			INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
		WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 2, 3)
			AND i.ExitDestinationID > 8
			AND i.DeletedDate IS NULL
			AND gt.GrantID = @GrantID
		GROUP BY x.ExitDestination
		ORDER BY ExitDestination; 

	-- Item 16 Educational Presentations
		SELECT PresentationID, YouthTargeted, PresentationHours, ISNULL(PrepHours, 0) AS PrepHours, NumberAttended, IsPresentation
		FROM Presentations
		WHERE PresentationDate BETWEEN @StartDate AND @EndDate
			AND DeletedDate IS NULL
		ORDER BY YouthTargeted; 

	-- Item 17 Staff Training
		SELECT st.StaffID, ts.SessionID, ts.SessionHours
		FROM TrainingSessions ts INNER JOIN StaffTraining st ON ts.SessionID = st.SessionID
			INNER JOIN Staff s ON st.StaffID = s.StaffID AND s.DeletedDate IS NULL
		WHERE ts.SessionDate BETWEEN @StartDate AND @EndDate AND ts.DeletedDate IS NULL; 

	-- Item 18 Hotline Calls
		SELECT c.CallSubjectID, COUNT(c.CallSubjectID) AS Calls
		FROM Calls c
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND c.DeletedDate IS NULL
			AND c.CallTypeID < 4 AND c.CallSubjectID > 0
			AND c.Walkin = 0
		GROUP BY c.CallSubjectID; 

	-- Item 18 Other Hotline Calls
		SELECT x.CallSubject + ' (' + CAST(COUNT(c.CallSubjectID) AS VARCHAR) + ')' AS Calls
		FROM Calls c INNER JOIN xCallSubject x ON c.CallSubjectID = x.CallSubjectID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate AND c.DeletedDate IS NULL
			AND c.CallTypeID < 4 AND c.CallSubjectID > 99  AND c.Walkin = 0
		GROUP BY x.CallSubject
		ORDER BY x.CallSubject; 

	-- Item 19 Outcomes
		SELECT qr.QuestionnaireID, qr.QuestionID, qr.Response
		FROM Grants 
g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
			INNER JOIN Surveys s ON s.SurveyID = gs.SurveyID
			INNER JOIN Questionnaires q ON s.SurveyID = q.SurveyID
			INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
		WHERE g.GrantorID = 2 
			AND ((@StartDate BETWEEN g.GrantStart AND g.GrantEnd)
				OR (@EndDate BETWEEN g.GrantStart AND g.GrantEnd))
			AND qr.QuestionID IN (1, 8, 9)
			AND q.CompletedDate BETWEEN @StartDate AND @EndDate
			AND g.DeletedDate IS NULL AND q.DeletedDate IS NULL
			AND s.DeletedDate IS NULL;

	-- Narratives
		SELECT
		Item3 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '3' AND DeletedDate IS NULL), ''),
		Item16 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '16' AND DeletedDate IS NULL), ''),
		Item20A = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '20A' AND DeletedDate IS NULL), ''),
		Item20B = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '20B' AND DeletedDate IS NULL), ''),
		Item20C = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '20C' AND DeletedDate IS NULL), ''),
		Contact = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Contact' AND DeletedDate IS NULL), ''),
		Phone = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Phone' AND DeletedDate IS NULL), ''),
		Email = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Email' AND DeletedDate IS NULL), ''),
		Attachment = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Attachment' AND DeletedDate IS NULL), ''); 

	-- Hotline Services
		SELECT gs.GrantorService, c.CallID, cs.NumberStaff * cs.SessionHours AS StaffHours
		FROM CallServices cs INNER JOIN Calls c ON cs.CallID = c.CallID
			INNER JOIN ServiceFocus sf ON cs.ServiceID = sf.ServiceID AND cs.FocusID = sf.FocusID
			INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
			INNER JOIN GrantorServices gs ON sm.GrantorServiceID = gs.GrantorServiceID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorID = 2 AND c.DeletedDate IS NULL
		ORDER BY gs.GrantorServiceID;

rpt_DVSRdetails
CREATE PROCEDURE dbo.rpt_DVSRdetails
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	DECLARE @GrantID INT
        SELECT TOP 1 @GrantID = GrantID
        FROM Grants
        WHERE DeletedDate IS NULL AND GrantorID = 2
            AND (@StartDate BETWEEN GrantStart AND GrantEnd
                OR @EndDate BETWEEN GrantStart ANd GrantEnd);

    -- Residential bednights
        -- NEW CRISIS/HOMELESS CLIENTS
        -- Crisis/Homeless Women
        SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, i.IntakeTypeID, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'F' AND p.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Crisis/Homeless Men
        SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, i.IntakeTypeID, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'M' AND p.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Crisis/Homeless Children
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, i.IntakeTypeID, Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END, NewClient = 1, ci.EntryDate, ci.ExitDate,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Child absences during period, i.e., negative bednights
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, i.IntakeTypeID, Bednights = CASE
            WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
            WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 1, ca.DateOut, ca.DateReturn,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.DeletedDate IS NULL
            AND ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND ca.DateOut BETWEEN @StartDate AND @EndDate
            AND gt.GrantID = @GrantID
        UNION ALL
        -- CARRYOVER CRISIS/HOMELESS CLIENTS
        -- Women Crisis/Homeless
        SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, i.IntakeTypeID, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'F' AND p.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Men Crisis/Homeless
        SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, i.IntakeTypeID, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID AND i.DeletedDate IS NULL
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.IntakeTypeID IN (1, 3) AND p.Sex = 'M' AND p.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Children Crisis/Homeless
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, i.IntakeTypeID, Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END, NewClient = 0, ci.EntryDate, ci.ExitDate,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.IntakeTypeID IN (1, 3) AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Child Absences Crisis/Homeless
        SELECT WomanID = 0, ManID = 0, ChildID = ci.Chi
ldID, i.IntakeTypeID, Bednights = CASE
            WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
            WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END, NewClient = 0, ca.DateOut, ca.DateReturn,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
            INNER JOIN Children c ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.DeletedDate IS NULL
            AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ca.DateOut <= @EndDate
            AND (ca.DateReturn IS NULL OR ca.DateReturn > @StartDate)
            AND gt.GrantID = @GrantID
        UNION ALL
        -- TRANSITIONAL CLIENTS:  CHECKS FOR INTAKES LINKED TO OTHER TRANSITIONAL INTAKES
        -- New transitional women, no linked tran'l intake
        SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, HousingTypeID = 4, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1, i.EntryDate, i.ExitDate,
                p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND oi.IntakeID IS NULL
            AND i.IntakeTypeID = 2 AND p.Sex = 'F'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- New transitional men, no linked tran'l intake
        SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, HousingTypeID = 4, Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND oi.IntakeID IS NULL
            AND i.IntakeTypeID = 2 AND p.Sex = 'M'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- New transitional children, no linked tran'l intake
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END, NewClient = 1, ci.EntryDate, ci.ExitDate,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON c.ChildID = ci.ChildID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate AND oi.IntakeID IS NULL
            AND i.IntakeTypeID = 2
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Carry over transitional women, linkage irrelevant 
        SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, HousingTypeID = 4, Bednights = CASE
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.IntakeTypeID = 2 AND p.Sex = 'F'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Carry over transitional men, linkage irrelevant 
        SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, HousingTypeID = 4, Bednights = CASE
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, i.ExitDate) END, NewClient = 0, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.IntakeTypeID = 2 AND p.Sex = 'M'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Carry over transitional children, linkage irrelevant 
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END, NewClient = 0, ci.EntryDate, ci.ExitDate,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON c.ChildID = ci.ChildID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.IntakeTypeID = 2
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Transitional women with intake during period gained from linked transitional intake
        -- Only compute the bednights for this intake; bednights for the originating intake
        -- are computed in the previous query
        SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0, HousingTypeID = 4, Bednights = CASE
   
         WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END,
            NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
            LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID = 2 AND p.Sex = 'F'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Transitional men with intake during period gained from linked transitional intake
        -- Only compute the bednights for this intake; bednights for the originating intake
        -- are computed in the previous query
        SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0, HousingTypeID = 4, Bednights = CASE
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END,
            NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END, i.EntryDate, i.ExitDate,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
            LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID = 2 AND p.Sex = 'M'
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        UNION ALL
        -- Transitional children with intake during period gained from linked transitional intake
        -- Only compute the bednights for this intake; bednights for the originating intake
        -- are computed in the previous query
        SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID, HousingTypeID = 4, Bednights = CASE
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END,
            NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END, ci.EntryDate, ci.ExitDate,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON c.ChildID = ci.ChildID
            INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
            INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
            LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID = 2
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
        ORDER BY NewClient DESC, ClientName, EntryDate;

    -- Individual Services
    -- ALL Crisis/Homeless/Non-Res DV/Non-Res Other Women
    SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup =
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE WHEN i.EntryDate < @StartDate THEN 0 ELSE 1 END,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 3, 4, 6) AND p.Sex = 'F'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- ALL Crisis/Homeless/Non-Res DV/ Non-Res Other Men
    SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE WHEN i.EntryDate < @StartDate THEN 0 ELSE 1 END,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 3, 4, 6) AND p.Sex = 'M'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- ALL Crisis/Homeless/Non-Res DV/Non-Res Other Children
    SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE WHEN ci.EntryDate < @StartDate THEN 0 ELSE 1 END,
        c.LastName + ', ' + c.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID 
= s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
        INNER JOIN Children c ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 3, 4, 6)
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Community Clients have no intake; label them as Non-Res DV (IntakeTypeID = 4) and not New,
    -- so they all appear in Item 11 non-residents.  Add 1000000 to their WomanID/ManID so they will
    -- be distinct from clients with intakes

    -- Community Client Women
    SELECT WomanID = cm.MemberID + 1000000, ManID = 0, ChildID = 0,
        IntakeTypeID = 5, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup =
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 0,
        cm.LastName + ', ' + cm.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND cm.Sex = 'F'
    UNION ALL

    -- Community Client Men
    SELECT WomanID = 0, ManID = cm.MemberID + 1000000, ChildID = 0,
        IntakeTypeID = 5, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup =
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 0,
        cm.LastName + ', ' + cm.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND cm.Sex = 'M'
    UNION ALL

    -- For transitional clients:
    -- NEW if no linked intake and entry date during report period
    -- NOT NEW IF entry date prior to report period
    -- NEW transitonal women, NO linked intake
    SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 1,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'F' AND oi.IntakeID IS NULL
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Carryover Transitional women; linked intake irrelevant
    SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 0,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate < @StartDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'F'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Transitional women with intake linked to another transitional intake; may or may not be new
    SELECT WomanID = p.ParticipantID, ManID = 0, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END,
         p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
        LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDa
te
        AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'F'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- NEW transitonal men, NO linked intake
    SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup =
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 1,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'M' AND oi.IntakeID IS NULL
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Carryover Transitional men; linked intake irrelevant
    SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 0,
        p.LastName + ', ' + p.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate < @StartDate 
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'M'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Transitional men with intake linked to another transitional intake; may or may not be new
    SELECT WomanID = 0, ManID = p.ParticipantID, ChildID = 0,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END,
        p.LastName + ', ' + p.FirstName AS ClientName
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
        LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND p.Sex = 'M'
        AND gt.GrantID = @GrantID
    UNION ALL
    -- NEW transitonal children, NO linked intake
    SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 1,
        c.LastName + ', ' + c.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
        INNER JOIN Children c ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID 
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        LEFT OUTER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND ci.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2 AND oi.IntakeID IS NULL
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Carryover Transitional children; linked intake irrelevant
    SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = 0,
        c.LastName + ', ' + c.FirstName AS ClientName
    --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
        INNER JOIN Children c ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND ci.EntryDate < @StartDate 
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 
2
        AND gt.GrantID = @GrantID
    UNION ALL
    -- Transitional children with intake linked to another transitional intake; may or may not be new
    SELECT WomanID = 0, ManID = 0, ChildID = ci.ChildID,
        i.IntakeTypeID, sm.GrantorServiceID, s.SessionHours, s.NumberStaff, s.SessionDate,
        NumberInGroup = 
        (SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL),
        NewClient = CASE
            WHEN oi.EntryDate < @StartDate THEN 0
            WHEN oi2.EntryDate < @StartDate THEN 0
            ELSE 1 END,
        c.LastName + ', ' + c.FirstName AS ClientName
    FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
        INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
        INNER JOIN Children c ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        INNER JOIN Intakes oi ON li.OriginIntakeID = oi.IntakeID AND oi.IntakeTypeID = 2
        INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        LEFT OUTER JOIN LinkedIntakes li2 ON oi.IntakeID = li2.GainingIntakeID
        LEFT OUTER JOIN Intakes oi2 ON li2.OriginIntakeID = oi2.IntakeID AND oi2.IntakeTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND ci.EntryDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID IN (201, 203, 205)
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.IntakeTypeID = 2
        AND gt.GrantID = @GrantID
    ORDER BY NewClient DESC, GrantorServiceID, WomanID, ManID, ChildID, ClientName, SessionDate;

    -- Group Services
        SELECT ClientType = 'Participant', s.SessionID, ClientID = 'P' + CAST(p.ParticipantID AS VARCHAR),
            p.Sex, s.SessionDate, s.SessionHours, s.NumberStaff, ClientTypeID = 1, i.IntakeTypeID,
            p.LastName + ', ' + p.FirstName AS ClientName
        --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID = 202
            AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        UNION ALL
        SELECT ClientType = 'Child', s.SessionID, ClientID = 'C' + CAST(ci.ChildID AS VARCHAR),
            c.Sex, s.SessionDate, s.SessionHours, s.NumberStaff, ClientTypeID = 2, i.IntakeTypeID,
            c.LastName + ', ' + c.FirstName AS ClientName
        --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID = 202
            AND i.DeletedDate IS NULL AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL
            AND cs.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        UNION ALL
        SELECT ClientType = 'Community', s.SessionID, ClientID = 'M' + CAST(cm.MemberID AS VARCHAR),
            cm.Sex, s.SessionDate, s.SessionHours, s.NumberStaff, ClientTypeID = 1, IntakeTypeID = 0,
            cm.LastName + ', ' + cm.FirstName AS ClientName
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID  AND s.FocusID = sf.FocusID 
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID = 202
            AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        ORDER BY SessionDate, s.SessionID;

    -- TANF Eligibility
        -- Query uses UNION vs UNION ALL so rows will be unique
        -- Primary Clients
        SELECT ClientTypeID = 1, p.ParticipantID AS ClientID,
            p.LastName + ', ' + p.FirstName AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID <> 5
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
            AND TANF_Eligible = 1
        UNION
        -- Children 
        SELECT ClientType = 2, c.ChildID + 1000000 AS ClientID,
            c.LastName + ', ' + c.FirstName
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID <> 5
            AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND gt.GrantID = @GrantID
            AND i.TANF_Eligible = 1
        ORDER BY ClientName;

rpt_ExitData
CREATE PROCEDURE dbo.rpt_ExitData
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	SELECT i.IntakeID, ShelterName, IntakeType, i.IntakeTypeID, LastName + ', ' + FirstName AS FullName, i.EntryDate, i.ExitDate,
        i.MentalIllness, i.PhysDisability, i.DevDisability, i.HIVAIDS, Location, Employment, ProtectionOrder, CourtCase, i.CourtOutcomeID,
        i.IncomeExit, SSIExit, SSDIExit, SSExit, GenPubAssistanceExit, TANFExit, ChildSupportExit, VetBenefitsExit,
        EmploymentIncomeExit, UnemploymentBenefitsExit, MedicareExit, MedicaidExit, FoodStampsExit, NoFinancialResourcesExit,
        WICExit, LowIncomeHousingExit, KidsCareExit, AHCCCSExit, CashAssistanceExit, IncomeOtherExit, PermanentSafeHousing = CASE
            WHEN i.PermanentSafeHousing IS NULL THEN -1 ELSE i.PermanentSafeHousing END,
        DATEDIFF(day, i.EntryDate, i.ExitDate) AS LOS,
        DATEDIFF(year, p.DOB, i.EntryDate) AS Age, DOB,
        ISNULL(ExitDestination, 'Unknown') AS ExitDestination,
        ISNULL(ExitHousing, 'Unknown') AS ExitHousing,
        ISNULL(ExitReason, 'Unknown') AS ExitReason,
        ISNULL(CourtOutcome, 'N/A') AS CourtOutcome,
        ISNULL(COUNT(ChildIntakeID), 0) AS NumberChildren
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN xIntakeType xit ON xit.IntakeTypeID = i.IntakeTypeID
        INNER JOIN xLocation xloc ON xloc.LocationID = i.LocationID
        INNER JOIN xEmployment xemp ON xemp.EmploymentID = i.EmploymentExitID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
        LEFT OUTER JOIN xExitHousing xeh ON xeh.ExitHousingID = i.ExitHousingID
        LEFT OUTER JOIN xExitDestination xed ON xed.ExitDestinationID = i.ExitDestinationID
        LEFT OUTER JOIN xExitReason xer ON xer.ExitReasonID = i.ExitReasonID
        LEFT OUTER JOIN xCourtOutcome xco ON xco.CourtOutcomeID = i.CourtOutcomeID
    WHERE i.ExitDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL
    GROUP BY i.IntakeID, ShelterName, IntakeType, i.IntakeTypeID, LastName, FirstName, i.EntryDate, i.ExitDate, Location, Employment,
        ProtectionOrder, CourtCase, ExitDestination, ExitHousing, ExitReason, CourtOutcome, i.CourtOutcomeID,
        i.MentalIllness, i.PhysDisability, i.DevDisability, i.HIVAIDS, p.DOB,
        i.IncomeExit, SSIExit, SSDIExit, SSExit, GenPubAssistanceExit, TANFExit, ChildSupportExit, VetBenefitsExit,
        EmploymentIncomeExit, UnemploymentBenefitsExit, MedicareExit, MedicaidExit, FoodStampsExit, NoFinancialResourcesExit,
        WICExit, LowIncomeHousingExit, KidsCareExit, AHCCCSExit, CashAssistanceExit, IncomeOtherExit, PermanentSafeHousing
    ORDER BY ShelterName, IntakeType, FullName

rpt_FVPSA
CREATE PROCEDURE rpt_FVPSA
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Clients Served
	-- Resident Participants
	SELECT p.ParticipantID AS ClientID, p.DOB, Age = 0, p.Sex, p.EthnicityID, p.LGBT,
		ivt.VictimTypeID, i.EntryDate, i.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
	WHERE i.DeletedDate IS NULL AND p.DeletedDate IS NULL
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99 AND i.IntakeTypeID IN (1, 2, 3, 5)
	UNION ALL
	-- Resident Children
	SELECT c.ChildID + 1000000 AS ClientID, c.DOB, Age = 0, c.Sex, c.EthnicityID, LGBT = CAST(0 AS BIT),
		ivt.VictimTypeID, ci.EntryDate, ci.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN IntakeVictimType ivt on ivt.IntakeID = i.IntakeID
	WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
		AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		AND ivt.VictimTypeID BETWEEN 3 AND 99 AND i.IntakeTypeID IN (1, 2, 3, 5)
	UNION ALL
	-- NonResident Participants who received an FVPSA service
	SELECT DISTINCT p.ParticipantID AS ClientID, p.DOB, Age = 0, p.Sex, p.EthnicityID, p.LGBT,
		ivt.VictimTypeID, i.EntryDate, i.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
		INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
		INNER JOIN Sessions s ON cs.SessionID = s.SessionID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ServiceMap sm ON sm.ServiceFocusID = sf.ServiceFocusID
	WHERE i.IntakeTypeID IN (4, 6)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate 
		AND ivt.VictimTypeID BETWEEN 3 AND 99
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006
		AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
	UNION ALL
	-- NonResident Children who received an FVPSA service
	SELECT DISTINCT c.ChildID + 1000000 AS ClientID, c.DOB, Age = 0, c.Sex, c.EthnicityID, LGBT = CAST(0 AS BIT),
		ivt.VictimTypeID, ci.EntryDate, ci.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
		INNER JOIN ClientSessions cs ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
		INNER JOIN Sessions s ON cs.SessionID = s.SessionID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ServiceMap sm ON sm.ServiceFocusID = sf.ServiceFocusID
	WHERE i.IntakeTypeID IN (4, 6)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate 
		AND ivt.VictimTypeID BETWEEN 3 AND 99
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006
		AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL	
	UNION ALL
	-- Community Members who received a mapped service
	SELECT DISTINCT cm.MemberID + 2000000 AS ClientID, cm.DOB, Age = 0, cm.Sex, cm.EthnicityID, LGBT = CAST(0 AS BIT),
		cm.VictimTypeID, EntryDate = NULL, ExitDate = NULL, IntakeTypeID = 4, cm.IsYouth
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
	WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006 AND cm.VictimTypeID > 0
		AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
	ORDER BY ClientID, i.IntakeTypeID;
	-- Other Demographics
	-- Not primary English speaker
	SELECT DISTINCT i.ParticipantID
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99
		AND i.LanguageID > 2;
	-- LGBT
	SELECT DISTINCT i.ParticipantID
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99
		AND p.LGBT = 1;
	-- Teen dating violence
	SELECT i.ParticipantID, i.EntryDate, p.DOB
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID = 12
	UNION ALL
	SELECT DISTINCT MemberID + 1000000, NULL, NULL
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
	WHERE cm.VictimTypeID = 12
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006 AND cm.VictimTypeID > 0
		AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL;

	-- Shelter Services:  Bednights & Hotline calls
	SELECT HotlineCalls =
	(
	-- Hotline Calls
	SELECT COUNT(CallID) AS HotlineCalls
	FROM Calls
	WHERE CallDate BETWEEN @StartDate AND @EndDate
		AND DeletedDate IS NULL
		AND CallTypeID < 4
	),
	ShelterDenied =
	(
		SELECT COUNT(c.CallID)
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND c.DeletedDate IS NULL
			AND sr.RequestOutcomeID = 1
	),
	Bednights = 
		(
	-- Bednights
	SELECT SUM(Bednights)
	FROM
	(
		SELECT CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.EntryDate >= @StartDate AND i.ExitDate <= @EndDate THEN DATEDIFF(day, i.EntryDate, i.ExitDate)
			WHEN i.EntryDate >= @StartDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.EntryDate < @StartDate AND i.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, i.ExitDate)
			WHEN i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			 END AS Bednights
		FROM Intakes i INNER JOIN (SELECT IntakeID, MIN(VictimTypeID) VictimTypeID FROM IntakeVictimType GROUP BY IntakeID) AS ivt
			ON i.IntakeID = ivt.IntakeID
		WHERE i.IntakeTypeID < 4 
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.DeletedDate IS NULL AND i.DeletedDate IS NULL
		UNION ALL
		SELECT CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.EntryDate >= @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, ci.EntryDate, ci.ExitDate)
			WHEN ci.EntryDate >= @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			WHEN ci.EntryDate < @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, i.ExitDate)
			WHEN ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			 END
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			 INNER JOIN (SELECT IntakeID,
 MIN(VictimTypeID) VictimTypeID FROM IntakeVictimType GROUP BY IntakeID) AS ivt
			 ON i.IntakeID = ivt.IntakeID
		WHERE i.IntakeTypeID < 4 
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
		) AS Bednights
	);

	-- Services to Victims
	
	-- Participant Victims
	SELECT p.ParticipantID AS ClientID, i.EntryDate, p.DOB, Age = 0, IsYouth = CAST(0 AS BIT), sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE sm.GrantorID = 10
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND (SELECT TOP 1 IntakeID FROM IntakeVictimType WHERE IntakeID = i.IntakeID) IS NOT NULL
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
	UNION ALL
	-- Child Victims 
	SELECT c.ChildID + 1000000 AS ClientID, ci.EntryDate, c.DOB, Age = 0, IsYouth = CAST(1 AS BIT), sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
		INNER JOIN Children c ON ci.ChildID = c.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID 
	WHERE sm.GrantorID = 10
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND (SELECT TOP 1 IntakeID FROM IntakeVictimType WHERE IntakeID = i.IntakeID) IS NOT NULL
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
	UNION ALL
	-- Community Member Victim services
	SELECT cm.MemberID + 2000000 AS ClientID, EntryDate = NULL, cm.DOB, Age = 0, cm.IsYouth, sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
	WHERE sm.GrantorID = 10 AND cm.VictimTypeID > 0
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND cm.DeletedDate IS NULL
	ORDER BY ClientID;

	-- Presentations
	SELECT PresentationID, NumberAttended, YouthTargeted
	FROM Presentations
	WHERE PresentationDate BETWEEN @StartDate AND @EndDate
		AND DeletedDate IS NULL;

	-- Narratives
	SELECT
		A01 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-01'), ''),
		A02 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-02'), ''),
		A03 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-03'), ''),
		A04 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-04'), ''),
		H01 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-01'), ''),
		H02 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-02'), ''),
		H03 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-03'), ''),
		H04 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-04'), ''),
		H05 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-05'), ''),
		H06 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-06'), '');

	-- Core Outcomes
		SELECT q.QuestionnaireID, qr.Response, qq.IsResource, qq.IsSafety,
			qq.IsShelter, qq.IsServices, qq.IsCounseling, qq.IsGroup
		FROM Grants g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
			INNER JOIN Surveys s ON s.SurveyID = gs.SurveyID
			INNER JOIN Questionnaires q ON s.SurveyID = q.SurveyID
			INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
			INNER JOIN Questions qq ON qr.QuestionID = qq.QuestionID
		WHERE g.GrantorID = 10
			AND (IsResource = 1 OR IsSafety = 1) 
			AND ((@StartDate BETWEEN g.GrantStart AND g.GrantEnd) 
				OR (@EndDate BETWEEN g.GrantStart AND g.GrantEnd))
			AND q.CompletedDate BETWEEN @StartDate ANd @EndDate
			AND g.DeletedDate IS NULL AND q.DeletedDate IS NULL AND s.DeletedDate IS NULL; 

rpt_FVPSAquarterly


CREATE PROCEDURE rpt_FVPSAquarterly
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Clients Served
	-- Resident Participants
	SELECT p.ParticipantID AS ClientID, p.DOB, Age = 0, p.Sex, p.EthnicityID, p.LGBT,
		ivt.VictimTypeID, i.EntryDate, i.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
	WHERE i.DeletedDate IS NULL AND p.DeletedDate IS NULL
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99 AND i.IntakeTypeID IN (1, 2, 3, 5)
	UNION ALL
	-- Resident Children
	SELECT c.ChildID + 1000000 AS ClientID, c.DOB, Age = 0, c.Sex, c.EthnicityID, LGBT = CAST(0 AS BIT),
		ivt.VictimTypeID, ci.EntryDate, ci.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN IntakeVictimType ivt on ivt.IntakeID = i.IntakeID
	WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
		AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		AND ivt.VictimTypeID BETWEEN 3 AND 99 AND i.IntakeTypeID IN (1, 2, 3, 5)
	UNION ALL
	-- NonResident Participants who received an FVPSA service
	SELECT DISTINCT p.ParticipantID AS ClientID, p.DOB, Age = 0, p.Sex, p.EthnicityID, p.LGBT,
		ivt.VictimTypeID, i.EntryDate, i.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
		INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
		INNER JOIN Sessions s ON cs.SessionID = s.SessionID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ServiceMap sm ON sm.ServiceFocusID = sf.ServiceFocusID
	WHERE i.IntakeTypeID IN (4, 6)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate 
		AND ivt.VictimTypeID BETWEEN 3 AND 99
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006
		AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
	UNION ALL
	-- NonResident Children who received an FVPSA service
	SELECT DISTINCT c.ChildID + 1000000 AS ClientID, c.DOB, Age = 0, c.Sex, c.EthnicityID, LGBT = CAST(0 AS BIT),
		ivt.VictimTypeID, ci.EntryDate, ci.ExitDate, i.IntakeTypeID, IsYouth = CAST(0 AS BIT)
	FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
		INNER JOIN ClientSessions cs ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
		INNER JOIN Sessions s ON cs.SessionID = s.SessionID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ServiceMap sm ON sm.ServiceFocusID = sf.ServiceFocusID
	WHERE i.IntakeTypeID IN (4, 6)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate 
		AND ivt.VictimTypeID BETWEEN 3 AND 99
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006
		AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL	
	UNION ALL
	-- Community Members who received a mapped service
	SELECT DISTINCT cm.MemberID + 2000000 AS ClientID, cm.DOB, Age = 0, cm.Sex, cm.EthnicityID, LGBT = CAST(0 AS BIT),
		cm.VictimTypeID, EntryDate = NULL, ExitDate = NULL, IntakeTypeID = 4, cm.IsYouth
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
	WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006 AND cm.VictimTypeID > 0
		AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
	ORDER BY ClientID, i.IntakeTypeID;

	-- Other Demographics
	-- Not primary English speaker
	SELECT DISTINCT i.ParticipantID
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99
		AND i.LanguageID > 2;
	-- LGBT
	SELECT DISTINCT i.ParticipantID
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID  BETWEEN 3 AND 99
		AND p.LGBT = 1;
	-- Teen dating violence
	SELECT i.ParticipantID, i.EntryDate, p.DOB
	FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE i.DeletedDate IS NULL 
		AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		AND ivt.VictimTypeID = 12
	UNION ALL
	SELECT DISTINCT MemberID + 1000000, NULL, NULL
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
	WHERE cm.VictimTypeID = 12
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND sm.GrantorServiceID BETWEEN 1001 AND 1006 AND cm.VictimTypeID > 0
		AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL;

	-- Shelter Services:  Bednights & Hotline calls
	SELECT HotlineCalls =
	(
	-- Hotline Calls
	SELECT COUNT(CallID) AS HotlineCalls
	FROM Calls
	WHERE CallDate BETWEEN @StartDate AND @EndDate
		AND DeletedDate IS NULL
		AND CallTypeID < 4
	),
	ShelterDenied =
	(
		SELECT COUNT(c.CallID)
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND c.DeletedDate IS NULL
			AND sr.RequestOutcomeID = 1
	),
	Bednights = 
		(
	-- Bednights
	SELECT SUM(Bednights)
	FROM
	(
		SELECT CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.EntryDate >= @StartDate AND i.ExitDate <= @EndDate THEN DATEDIFF(day, i.EntryDate, i.ExitDate)
			WHEN i.EntryDate >= @StartDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.EntryDate < @StartDate AND i.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, i.ExitDate)
			WHEN i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			 END AS Bednights
		FROM Intakes i INNER JOIN (SELECT IntakeID, MIN(VictimTypeID) VictimTypeID FROM IntakeVictimType GROUP BY IntakeID) AS ivt
			ON i.IntakeID = ivt.IntakeID
		WHERE i.IntakeTypeID < 4 
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
			AND i.DeletedDate IS NULL AND i.DeletedDate IS NULL
		UNION ALL
		SELECT CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.EntryDate >= @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, ci.EntryDate, ci.ExitDate)
			WHEN ci.EntryDate >= @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			WHEN ci.EntryDate < @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, i.ExitDate)
			WHEN ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			 END
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			 INNER JOIN 
(SELECT IntakeID, MIN(VictimTypeID) VictimTypeID FROM IntakeVictimType GROUP BY IntakeID) AS ivt
			 ON i.IntakeID = ivt.IntakeID
		WHERE i.IntakeTypeID < 4 
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
			AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
		) AS Bednights
	);

	-- Services to Victims
	
	-- Participant Victims
	SELECT p.ParticipantID AS ClientID, i.EntryDate, p.DOB, Age = 0, IsYouth = CAST(0 AS BIT), sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID AND cs.ClientTypeID = 1
		INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
	WHERE sm.GrantorID = 10
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND (SELECT TOP 1 IntakeID FROM IntakeVictimType WHERE IntakeID = i.IntakeID) IS NOT NULL
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
	UNION ALL
	-- Child Victims 
	SELECT c.ChildID + 1000000 AS ClientID, ci.EntryDate, c.DOB, Age = 0, IsYouth = CAST(1 AS BIT), sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
		INNER JOIN Children c ON ci.ChildID = c.ChildID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID 
	WHERE sm.GrantorID = 10
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND (SELECT TOP 1 IntakeID FROM IntakeVictimType WHERE IntakeID = i.IntakeID) IS NOT NULL
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
	UNION ALL
	-- Community Member Victim services
	SELECT cm.MemberID + 2000000 AS ClientID, EntryDate = NULL, cm.DOB, Age = 0, cm.IsYouth, sm.GrantorServiceID
	FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
		INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
	WHERE sm.GrantorID = 10 AND cm.VictimTypeID > 0
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND cm.DeletedDate IS NULL
	ORDER BY ClientID;

	-- Presentations
	SELECT PresentationID, NumberAttended, YouthTargeted
	FROM Presentations
	WHERE PresentationDate BETWEEN @StartDate AND @EndDate
		AND DeletedDate IS NULL;

	-- Narratives
	SELECT
		A = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A'), ''),
		B = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'B'), '');

rpt_GenericReport
CREATE PROCEDURE rpt_GenericReport
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @False BIT = 0, @True BIT = 0,
	@ShelterIDs AS dbo.IdTable READONLY, @ProgramIDs AS dbo.IdTable READONLY,
	@ServiceIDs AS dbo.IdTable READONLY, @StaffIDs AS dbo.IdTable READONLY)
	AS
	-- Query for shelter related data      
    SELECT ClientType = 1, s.ShelterName, p.ParticipantID AS ClientID, i.IntakeID, xi.IntakeType,
        LastName + ', ' + FirstName + ' ' + MI AS FullName, DOB, Sex, p.EthnicityID,
        i.EntryDate, i.ExitDate, DATEDIFF(year, DOB, i.EntryDate) AS Age, Bednights = 0,
        Ethnicity = CASE WHEN p.EthnicityID = 1 THEN 'Unknown' WHEN p.EthnicityID = 7 THEN 'Native Am.' ELSE Ethnicity END,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        TANF_Eligible, SSI, SSDI, SS, GenPubAssistance, ChildSupport, VetBenefits, EmploymentIncome,
        UnemploymentBenefits, FoodStamps, NoFinancialResources, WIC, LowIncomeHousing, KidsCare,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        Medicaid = CASE WHEN Medicaid = 1 OR AHCCCS = 1 THEN @True ELSE @False END,
        IncomeOther = CASE WHEN LEN(IncomeOther) > 0 THEN @True ELSE @False END,
        Income = ISNULL(IncomeEntry * 12, -1), 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM Shelters s
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON p.ParticipantID = ta.ClientID AND ta.ClientTypeID = 1
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ShelterID IN (SELECT ID FROM @ShelterIDs) 
		AND i.EntryDate <= @EndDate
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 2, s.ShelterName, c.ChildID AS ClientID, ci.IntakeID, xi.IntakeType,
        LastName + ', ' + FirstName + ' ' + MI AS FullName,	DOB, Sex, c.EthnicityID,
        ci.EntryDate, ci.ExitDate, DATEDIFF(year, DOB, ci.EntryDate) AS Age, Bednights = 0,
        Ethnicity = CASE WHEN c.EthnicityID = 1 THEN 'Unknown' WHEN c.EthnicityID = 7 THEN 'Native Am.' ELSE Ethnicity END,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        ci.TanfEligible, ci.SSI, ci.SSDI, @False, @False, @False, @False, @False,
        @False, ci.FoodStamps, @False, ci.WIC, ci.LowIncomeHousing, ci.KidsCare,
        TANF = CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN @True ELSE @False END,
        @False, @False, -1, 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM Shelters s
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
        INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON c.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON c.ChildID = ta.ClientID AND ta.ClientTypeID = 2
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ShelterID IN (SELECT ID FROM @ShelterIDs)
		AND ci.EntryDate <= @EndDate
        AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
        AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
		-- Don't count children w/o exit date if parent has exited
		AND i.EntryDate <= @EndDate
		AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL
    ORDER BY ShelterName, IntakeType, IntakeID, ClientType, FullName;

	-- Query for Program related data        
    SELECT ClientType = 1, pp.Program, ss.ServiceName, p.ParticipantID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (P)' AS FullName,
        DOB, Sex, p.EthnicityID, i.EntryDate, DATEDIFF(year, DOB, i.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN p.EthnicityID = 1 THEN 'Unknown' WHEN p.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        s.SessionHours, StaffHours = 
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        TANF_Eligible, SSI, SSDI, SS, GenPubAssistance, ChildSupport, VetBenefits, EmploymentIncome,
        UnemploymentBenefits, FoodStamps, NoFinancialResources, WIC, LowIncomeHousing, KidsCare,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        Medicaid = CASE WHEN Medicaid = 1 OR AHCCCS = 1 THEN @True ELSE @False END,
        IncomeOther = CASE WHEN LEN(IncomeOther) > 0 THEN @True ELSE @False END,
        Income = ISNULL(IncomeEntry * 12, -1), 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM Programs pp
        INNER JOIN [Sessions] s ON s.ProgramID = pp.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Participants p ON cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
        INNER JOIN Intakes i ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON p.ParticipantID = ta.ClientID AND ta.ClientTypeID = 1
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ProgramID IN (SELECT ID FROM @ProgramIDs) 
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 2, pp.Program, ss.ServiceName, c.ChildID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (C)' AS FullName,
        DOB, Sex, c.EthnicityID, ci.EntryDate, DATEDIFF(year, DOB, ci.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN c.EthnicityID = 1 THEN 'Unknown' WHEN c.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethni
city END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        s.SessionHours, StaffHours =
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        ci.TanfEligible, ci.SSI, ci.SSDI, @False, @False, @False, @False, @False,
        @False, ci.FoodStamps, @False, ci.WIC, ci.LowIncomeHousing, ci.KidsCare,
        TANF = CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN @True ELSE @False END,
        @False, @False, -1, 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM Programs pp
        INNER JOIN [Sessions] s ON s.ProgramID = pp.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Children c ON cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
        INNER JOIN ChildIntakes ci ON ci.ChildIntakeID = cs.IntakeID AND cs.ClientTypeID = 2
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON c.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON c.ChildID = ta.ClientID AND ta.ClientTypeID = 2
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ProgramID IN (SELECT ID FROM @ProgramIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 3, pp.Program, ss.ServiceName, a.AbuserID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (P)' AS FullName,
        DOB, Sex, a.EthnicityID, ai.EntryDate, DATEDIFF(year, DOB, ai.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN a.EthnicityID = 1 THEN 'Unknown' WHEN a.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        s.SessionHours, StaffHours = 
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        @False, ai.SSI, ai.SSDI, @False, @False, @False, @False, @False,
        @False, ai.FoodStamps, @False, ai.WIC, ai.LowIncomeHousing, @False,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        ai.AHCCCS, @False, Income = ISNULL(Income * 12, -1), 
		1, 0, 1, 1, 1, 1, 1
    FROM Programs pp
        INNER JOIN [Sessions] s ON s.ProgramID = pp.ProgramID
        INNER JOIN [Services] ss ON ss.ServiceID = s.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Abusers a ON cs.ClientID = a.AbuserID AND cs.ClientTypeID = 3
        INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID AND cs.ClientTypeID = 3
        INNER JOIN xEthnicity xe ON xe.EthnicityID = a.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON a.AbuserID = ta.ClientID and ta.ClientTypeID = 3
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ProgramID IN (SELECT ID FROM @ProgramIDs) 
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND a.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND ai.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 4, pp.Program, ss.ServiceName, cm.MemberID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (M)' AS FullName,
        DOB, Sex, cm.EthnicityID, EntryDate = NULL, Age = -1,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN cm.EthnicityID = 1 THEN 'Unknown' WHEN cm.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        s.SessionHours, StaffHours =
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        TANF_Eligible = @False, SSI = @False, SSDI = @False, SS = @False, GenPubAssistance = @False, ChildSupport = @False, VetBenefits = @False, EmploymentIncome = @False,
        UnemploymentBenefits = @False, FoodStamps = @False, NoFinancialResources = @False, WIC = @False, LowIncomeHousing = @False, KidsCare = @False,
        TANF = @False, Medicaid = @False, IncomeOther = @False, Income = -1, 
		1, 0, 1, 1, 1, 1, 1
    FROM Programs pp INNER JOIN[Sessions] s ON s.ProgramID = pp.ProgramID
        INNER JOIN Services ss ON s.ServiceID = s.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
        INNER JOIN xEthnicity xe ON cm.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON cm.MemberID = ta.ClientID AND ta.ClientTypeID = 4
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ProgramID IN (SELECT ID FROM @ProgramIDs)     
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL
    ORDER BY Program, ServiceName, ClientType, ClientID;

	-- Query for Service related data        
    SELECT ClientType = 1, ss.ServiceName, p.ParticipantID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (P)' AS FullName,
        DOB, Sex, p.EthnicityID, i.EntryDate, DATEDIFF(year, DOB, i.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN p.EthnicityID = 1 THEN 'Unknown' WHEN p.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        s.SessionHours, StaffHours =
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        TANF_Eligible, SSI, SSDI, SS, GenPubAssistance, ChildSupport, VetBenefits, EmploymentIncome,
        UnemploymentBenefits, FoodStamps, NoFinancialResources, WIC, LowIncomeHousing, KidsCare,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        Medicaid = CASE WHEN Medicaid = 1 OR AHCCCS = 1 THEN @True ELSE @False END,
        IncomeOther = CASE WHEN LEN(IncomeOther) > 0 THEN @True ELSE @False END,
        Income = ISNULL(IncomeEntry * 12, -1), 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM [Services] ss
        INNER JOIN [Sessions] s ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Participants p ON cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
        INNER JOIN Intakes i ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.Ethnicit
yID
        LEFT OUTER JOIN TribalAffiliation ta ON p.ParticipantID = ta.ClientID AND ta.ClientTypeID = 1
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ServiceID IN (SELECT ID FROM @ServiceIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 2, ss.ServiceName, c.ChildID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (C)' AS FullName,
        DOB, Sex, c.EthnicityID, ci.EntryDate, DATEDIFF(year, DOB, ci.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN c.EthnicityID = 1 THEN 'Unknown' WHEN c.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        s.SessionHours, StaffHours = 
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        ci.TanfEligible, ci.SSI, ci.SSDI, @False, @False, @False, @False, @False,
        @False, ci.FoodStamps, @False, ci.WIC, ci.LowIncomeHousing, ci.KidsCare,
        TANF = CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN @True ELSE @False END,
        @False, @False, -1, 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM [Services] ss
        INNER JOIN [Sessions] s ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Children c ON cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
        INNER JOIN ChildIntakes ci ON ci.ChildIntakeID = cs.IntakeID AND cs.ClientTypeID = 2
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON c.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON c.ChildID = ta.ClientID AND ta.ClientTypeID = 2
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ServiceID IN (SELECT ID FROM @ServiceIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 3, ss.ServiceName, a.AbuserID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (A)' AS FullName,
        DOB, Sex, a.EthnicityID, ai.EntryDate, DATEDIFF(year, DOB, ai.EntryDate) AS Age,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN a.EthnicityID = 1 THEN 'Unknown' WHEN a.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        s.SessionHours, StaffHours = 
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        @False, ai.SSI, ai.SSDI, @False, @False, @False, @False, @False,
        @False, ai.FoodStamps, @False, ai.WIC, ai.LowIncomeHousing, @False,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        ai.AHCCCS, @False, Income = ISNULL(Income * 12, -1), 
		1, 0, 1, 1, 1, 1, 1
    FROM [Services] ss
        INNER JOIN [Sessions] s ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN Abusers a ON cs.ClientID = a.AbuserID AND cs.ClientTypeID = 3
        INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID AND cs.ClientTypeID = 3
        INNER JOIN xEthnicity xe ON xe.EthnicityID = a.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON a.AbuserID = ta.ClientID and ta.ClientTypeID = 3
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ServiceID IN (SELECT ID FROM @ServiceIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND a.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND ai.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 4, ss.ServiceName, cm.MemberID AS ClientID, RTRIM(LastName + ', ' + FirstName + ' ' + MI) + ' (M)' AS FullName,
        DOB, Sex, cm.EthnicityID, EntryDate = NULL, Age = -1,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN cm.EthnicityID = 1 THEN 'Unknown' WHEN cm.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        s.SessionHours, StaffHours =
        (s.NumberStaff * s.SessionHours /
            (SELECT COUNT(*) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)),
        TANF_Eligible = @False, SSI = @False, SSDI = @False, SS = @False, GenPubAssistance = @False, ChildSupport = @False, VetBenefits = @False, EmploymentIncome = @False,
        UnemploymentBenefits = @False, FoodStamps = @False, NoFinancialResources = @False, WIC = @False, LowIncomeHousing = @False, KidsCare = @False,
        TANF = @False, Medicaid = @False, IncomeOther = @False, Income = -1, 
		1, 0, 1, 1, 1, 1, 1
    FROM[Services] ss
        INNER JOIN[Sessions] s ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
        INNER JOIN xEthnicity xe ON cm.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON cm.MemberID = ta.ClientID AND ta.ClientTypeID = 4
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.ServiceID IN (SELECT ID FROM @ServiceIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL
    ORDER BY ClientType, ServiceName, ClientID;

	-- Query for Staff related data
    SELECT ClientType = 1, ss.ServiceName, s.SessionID, s.SessionDate, s.SessionHours,
        st.StaffID, st.LastName + ', ' + st.FirstName + ' ' + st.MI AS StaffName,
        DOB, Sex, p.EthnicityID, i.EntryDate, DATEDIFF(year, DOB, i.EntryDate) AS Age, 
        RTRIM(p.LastName + ', ' + p.FirstName + ' ' + p.MI) + ' (P)' AS ClientName, p.ParticipantID AS ClientID,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN p.EthnicityID = 1 THEN 'Unknown' WHEN p.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        TANF_Eligible, SSI, SSDI, SS, GenPubAssistance, ChildSupport, VetBenefits, EmploymentIncome,
        UnemploymentBenefits, FoodStamps, NoFinancialResources, WIC, LowIncomeHousing, KidsCare,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        Medicaid = CASE WHEN Medicaid = 1 OR AHCCCS = 1 THEN @True ELSE @False END,
        IncomeOther = CASE WHEN LEN(IncomeOther) > 0 THEN @True ELSE @False END,
        Income = ISNULL(IncomeEntry * 12, -1), 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyI
D, i.ReservationID
    FROM Staff st
        INNER JOIN StaffSessions sts ON st.StaffID = sts.StaffID
        INNER JOIN [Sessions] s ON sts.SessionID = s.SessionID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Participants p ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON p.ParticipantID = ta.ClientID AND ta.ClientTypeID = 1
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE sts.StaffID IN (SELECT ID FROM @StaffIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL AND st.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 2, ss.ServiceName, s.SessionID, s.SessionDate, s.SessionHours,
        st.StaffID, st.LastName + ', ' + st.FirstName + ' ' + st.MI AS StaffName,
        DOB, Sex, c.EthnicityID, ci.EntryDate, DATEDIFF(year, DOB, ci.EntryDate) AS Age,
        RTRIM(c.LastName + ', ' + c.FirstName + ' ' + c.MI) + ' (C)' AS ClientName, c.ChildID AS ClientID,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN c.EthnicityID = 1 THEN 'Unknown' WHEN c.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = CASE WHEN i.CountyID = 1 THEN 'Unknown' ELSE xc.County END,
        Location = CASE WHEN i.LocationID = 1 THEN 'Unknown' ELSE xl.Location END,
        Reservation = CASE WHEN i.ReservationID > 1 THEN xr.Reservation ELSE '' END,
        ci.TanfEligible, ci.SSI, ci.SSDI, @False, @False, @False, @False, @False,
        @False, ci.FoodStamps, @False, ci.WIC, ci.LowIncomeHousing, ci.KidsCare,
        TANF = CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN @True ELSE @False END,
        @False, @False, -1, 
		i.LocationID, i.MaritalStatusID, i.EmploymentID, i.LanguageID, i.CitizenshipID, i.CountyID, i.ReservationID
    FROM Staff st
        INNER JOIN StaffSessions sts ON st.StaffID = sts.StaffID
        INNER JOIN [Sessions] s ON sts.SessionID = s.SessionID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Children c ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xReservation xr ON i.ReservationID = xr.ReservationID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xEthnicity xe ON c.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON c.ChildID = ta.ClientID AND ta.ClientTypeID = 2
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE sts.StaffID IN (SELECT ID FROM @StaffIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL 
        AND st.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 3, ss.ServiceName, s.SessionID, s.SessionDate, s.SessionHours,
        st.StaffID, st.LastName + ', ' + st.FirstName + ' ' + st.MI AS StaffName,
        DOB, Sex, a.EthnicityID, ai.EntryDate, DATEDIFF(year, DOB, ai.EntryDate) AS Age,
        RTRIM(a.LastName + ', ' + a.FirstName + ' ' + a.MI) + ' (A)' AS ClientName, a.AbuserID AS ClientID,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN a.EthnicityID = 1 THEN 'Unknown' WHEN a.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        @False, ai.SSI, ai.SSDI, @False, @False, @False, @False, @False,
        @False, ai.FoodStamps, @False, ai.WIC, ai.LowIncomeHousing, @False,
        TANF = CASE WHEN TANF = 1 OR CashAssistance = 1 THEN @True ELSE @False END,
        ai.AHCCCS, @False, Income = ISNULL(Income * 12, -1), 
		1, 0, 1, 1, 1, 1, 1
    FROM Staff st
        INNER JOIN StaffSessions sts ON st.StaffID = sts.StaffID
        INNER JOIN [Sessions] s ON sts.SessionID = s.SessionID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Abusers a ON a.AbuserID = cs.ClientID AND cs.ClientTypeID = 3
        INNER JOIN AbuserIntakes ai ON ai.AbuserIntakeID = cs.IntakeID AND cs.ClientTypeID = 3
        INNER JOIN xEthnicity xe ON a.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON a.AbuserID = ta.ClientID AND ta.ClientTypeID = 3
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE sts.StaffID IN (SELECT ID FROM @StaffIDs)
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
        AND a.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND st.DeletedDate IS NULL
    UNION ALL
    SELECT ClientType = 4, ss.ServiceName, s.SessionID, s.SessionDate, s.SessionHours,
        st.StaffID, st.LastName + ', ' + st.FirstName + ' ' + st.MI AS StaffName,
        DOB, Sex, cm.EthnicityID, EntryDate = NULL, Age = -1,
        RTRIM(cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI) + ' (M)' AS ClientName, cm.MemberID AS ClientID,
        Tribe = CASE WHEN ta.TribeID IS NULL OR ta.TribeID = 1 THEN '' ELSE xt.Tribe END,
        Ethnicity = CASE WHEN cm.EthnicityID = 1 THEN 'Unknown' WHEN cm.EthnicityID = 7 THEN 'Native Am.' ELSE xe.Ethnicity END,
        County = '', Location = '', Reservation = '',
        TANF_Eligible = @False, SSI = @False, SSDI = @False, SS = @False, GenPubAssistance = @False, ChildSupport = @False, VetBenefits = @False, EmploymentIncome = @False,
        UnemploymentBenefits = @False, FoodStamps = @False, NoFinancialResources = @False, WIC = @False, LowIncomeHousing = @False, KidsCare = @False,
        TANF = @False, Medicaid = @False, IncomeOther = @False, Income = -1, 
		1, 0, 1, 1, 1, 1, 1
    FROM Staff st
        INNER JOIN StaffSessions sts ON st.StaffID = sts.StaffID
        INNER JOIN[Sessions] s ON sts.SessionID = s.SessionID
        INNER JOIN[Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
        INNER JOIN xEthnicity xe ON cm.EthnicityID = xe.EthnicityID
        LEFT OUTER JOIN TribalAffiliation ta ON cm.MemberID = ta.ClientID AND ta.ClientTypeID = 4
        LEFT OUTER JOIN xTribe xt ON ta.TribeID = xt.TribeID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND ss.DeletedDate IS NULL AND st.DeletedDate IS NULL
    ORDER BY StaffID, s.SessionID;


rpt_HotlineCallSummary
CREATE PROCEDURE dbo.rpt_HotlineCallSummary
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT ShelterID, ShelterName FROM Shelters s WHERE DeletedDate IS NULL AND s.IsCurrent = 1 ORDER BY ShelterID;
	--TotalCalls =         
    SELECT c.ShelterID, Count(*) AS TotalCalls
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate AND CallTypeID < 4
    GROUP BY c.ShelterID ORDER BY ShelterID;
	--CrisisCalls =           
    SELECT c.ShelterID, Count(*) AS CrisisCalls
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate AND CallTypeID IN (1, 3)
    GROUP BY c.ShelterID ORDER BY ShelterID;
	--InfoCalls =         
    SELECT c.ShelterID, Count(*) AS InfoCalls
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate AND CallTypeID IN (2, 3)
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Shelter Requests =           
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS ShelterRequests
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate
        AND CallTypeID < 4 AND sr.RequestOutcomeID IS NOT NULL
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- NoShows =            
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS NoShows
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 7
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- ShelterProvided =       
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS ShelterProvided 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID 
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID 
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate  
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 2 
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Total Denied =     
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS TotalDenied 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        INNER JOIN xReasonDenied x ON x.ReasonDeniedID = sr.ReasonDeniedID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 1
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Number Denied =   
    SELECT c.ShelterID, sr.ReasonDeniedID, ReasonDenied, SUM(NumberChildren + 1) AS NumberDenied 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        INNER JOIN xReasonDenied x ON x.ReasonDeniedID = sr.ReasonDeniedID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 1
    GROUP BY c.ShelterID, sr.ReasonDeniedID, ReasonDenied
    ORDER BY ShelterID, ReasonDeniedID;
	-- Locations =      
    SELECT s.ShelterName, x.Location, COUNT(c.LocationID) AS NumberCalls
    FROM Calls c INNER JOIN xLocation x ON c.LocationID = x.LocationID
        INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate AND c.DeletedDate IS NULL
    GROUP BY ShelterName, Location
    ORDER BY ShelterName, Location;
	-- Turnaways =
	SELECT c.ShelterID, COUNT(c.CallID) AS Turnaways
	FROM Calls c
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate 
		AND c.Turnaway = 1 AND c.DeletedDate IS NULL
	GROUP BY c.ShelterID
	ORDER BY c.ShelterID

	-- MISSION BASED REQUESTS
	-- ShelterRequests =
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS ShelterRequests
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate
        AND CallTypeID < 4 AND sr.RequestOutcomeID IS NOT NULL
        AND CallSubjectID BETWEEN 3 AND 99
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- No Shows =
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS NoShows
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 7
        AND CallSubjectID BETWEEN 3 AND 99
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Shelter Provided =
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS ShelterProvided 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID 
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID 
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate  
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 2 
        AND CallSubjectID BETWEEN 3 AND 99
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Total Denied =
    SELECT c.ShelterID, SUM(NumberChildren + 1) AS TotalDenied 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        INNER JOIN xReasonDenied x ON x.ReasonDeniedID = sr.ReasonDeniedID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 1
        AND CallSubjectID BETWEEN 3 AND 99
    GROUP BY c.ShelterID ORDER BY ShelterID;
	-- Number Denied =
    SELECT c.ShelterID, sr.ReasonDeniedID, ReasonDenied, SUM(NumberChildren + 1) AS NumberDenied 
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        INNER JOIN xReasonDenied x ON x.ReasonDeniedID = sr.ReasonDeniedID
    WHERE c.DeletedDate IS NULL AND c.CallDate BETWEEN @StartDate AND @EndDate 
        AND CallTypeID < 4 AND sr.RequestOutcomeID = 1
        AND CallSubjectID BETWEEN 3 AND 99
    GROUP BY c.ShelterID, sr.ReasonDeniedID, ReasonDenied
    ORDER BY ShelterID, ReasonDeniedID; 
	-- Turnaways =
	-- Turnaways =
	SELECT c.ShelterID, COUNT(c.CallID) AS Turnaways
	FROM Calls c
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate 
		AND c.Turnaway = 1 AND c.DeletedDate IS NULL
		AND CallSubjectID BETWEEN 3 AND 99
	GROUP BY c.ShelterID
	ORDER BY c.ShelterID 
	-- Hotline Referrals
    SELECT s.ShelterName, x.HotlineReferral, COUNT(hr.HotlineReferralID) AS Referrals
    FROM Calls c INNER JOIN HotlineReferrals hr ON c.CallID = hr.CallID
        INNER JOIN xHotlineReferral x ON hr.HotlineReferralID = x.HotlineReferralID
        INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate AND c.DeletedDate IS NULL
    GROUP BY ShelterName, HotlineReferral
    ORDER BY ShelterName, HotlineReferral;

rpt_HUD
CREATE PROCEDURE dbo.rpt_HUD
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Intakes that are gained from another transitional intake (continuation)
    -- Looks back for up to 5 linked, transitional intakes. 
    -- Entry data is taken from the first intake
    SELECT p.ParticipantID, LastName + ', ' + FirstName + '*' AS ParticipantName,
        p.DOB,
        ISNULL(i5.EntryDate, ISNULL(i4.EntryDate, ISNULL(i3.EntryDate, i2.EntryDate))) AS EntryDate,
        i1.ExitDate, Bednights = 0, LOS = 0, Age = 0, Sex, EthnicityID, Veteran,
        ISNULL(i5.MentalIllness, ISNULL(i4.MentalIllness, ISNULL(i3.MentalIllness, i2.MentalIllness))) AS MentalIllness,
        ISNULL(i5.PhysDisability, ISNULL(i4.PhysDisability, ISNULL(i3.PhysDisability, i2.PhysDisability))) AS PhysDisability,
        ISNULL(i5.DevDisability, ISNULL(i4.DevDisability, ISNULL(i3.DevDisability, i2.DevDisability))) AS DevDisability,
        ISNULL(i5.HIVAIDS, ISNULL(i4.HIVAIDS, ISNULL(i3.HIVAIDS, i2.HIVAIDS))) AS HIVAIDS,
        ISNULL(i5.SubstanceAbuseID, ISNULL(i4.SubstanceAbuseID, ISNULL(i3.SubstanceAbuseID, i2.SubstanceAbuseID))) AS SubstanceAbuseID,
        ISNULL(i5.PriorResidenceID, ISNULL(i4.PriorResidenceID, ISNULL(i3.PriorResidenceID, i2.PriorResidenceID))) AS PriorResidenceID,
        Conditions = 0,
        NumberChildren =
            (SELECT ISNULL(COUNT(ChildID), 0) FROM ChildIntakes ci
            WHERE ci.IntakeID = i1.IntakeID AND ci.DeletedDate IS NULL),
        ISNULL(i5.IncomeEntry, ISNULL(i4.IncomeEntry, ISNULL(i3.IncomeEntry, i2.IncomeEntry))) AS IncomeEntry,
        i1.IncomeExit, i1.ExitHousingID,
        ISNULL(i5.SSI, ISNULL(i4.SSI, ISNULL(i3.SSI, i2.SSI))) AS SSI,
        ISNULL(i5.SSDI, ISNULL(i4.SSDI, ISNULL(i3.SSDI, i2.SSDI))) AS SSDI,
        ISNULL(i5.SS, ISNULL(i4.SS, ISNULL(i3.SS, i2.SS))) AS SS,
        ISNULL(i5.GenPubAssistance, ISNULL(i4.GenPubAssistance, ISNULL(i3.GenPubAssistance, i2.GenPubAssistance))) AS GenPubAssistance,
        ISNULL(i5.TANF, ISNULL(i4.TANF, ISNULL(i3.TANF, i2.TANF))) AS TANF,
        ISNULL(i5.ChildSupport, ISNULL(i4.ChildSupport, ISNULL(i3.ChildSupport, i2.ChildSupport))) AS ChildSupport,
        ISNULL(i5.VetBenefits, ISNULL(i4.VetBenefits, ISNULL(i3.VetBenefits, i2.VetBenefits))) AS VetBenefits,
        ISNULL(i5.EmploymentIncome, ISNULL(i4.EmploymentIncome, ISNULL(i3.EmploymentIncome, i2.EmploymentIncome))) AS EmploymentIncome,
        ISNULL(i5.UnemploymentBenefits, ISNULL(i4.UnemploymentBenefits, ISNULL(i3.UnemploymentBenefits, i2.UnemploymentBenefits))) AS UnemploymentBenefits,
        ISNULL(i5.Medicare, ISNULL(i4.Medicare, ISNULL(i3.Medicare, i2.Medicare))) AS Medicare,
        ISNULL(i5.Medicaid, ISNULL(i4.Medicaid, ISNULL(i3.Medicaid, i2.Medicaid))) AS Medicaid,
        ISNULL(i5.FoodStamps, ISNULL(i4.FoodStamps, ISNULL(i3.FoodStamps, i2.FoodStamps))) AS FoodStamps,
        ISNULL(i5.NoFinancialResources, ISNULL(i4.NoFinancialResources, ISNULL(i3.NoFinancialResources, i2.NoFinancialResources))) AS NoFinancialResources,
        ISNULL(i5.WIC, ISNULL(i4.WIC, ISNULL(i3.WIC, i2.WIC))) AS WIC,
        ISNULL(i5.LowIncomeHousing, ISNULL(i4.LowIncomeHousing, ISNULL(i3.LowIncomeHousing, i2.LowIncomeHousing))) AS LowIncomeHousing,
        ISNULL(i5.KidsCare, ISNULL(i4.KidsCare, ISNULL(i3.KidsCare, i2.KidsCare))) AS KidsCare,
        ISNULL(i5.AHCCCS, ISNULL(i4.AHCCCS, ISNULL(i3.AHCCCS, i2.AHCCCS))) AS AHCCCS,
        ISNULL(i5.CashAssistance, ISNULL(i4.CashAssistance, ISNULL(i3.CashAssistance, i2.CashAssistance))) AS CashAssistance,
        ISNULL(i5.IncomeOther, ISNULL(i4.IncomeOther, ISNULL(i3.IncomeOther, i2.IncomeOther))) AS IncomeOther,
        CashSourceEntry = 0, CashSourceExit = 0, NonCashSourceEntry = 0, NonCashSourceExit = 0,
        i1.SSIExit, i1.SSDIExit, i1.SSExit, i1.GenPubAssistanceExit, i1.TANFExit, i1.ChildSupportExit, i1.VetBenefitsExit, i1.EmploymentIncomeExit,
        i1.UnemploymentBenefitsExit, i1.MedicareExit, i1.MedicaidExit, i1.FoodStampsExit, i1.NoFinancialResourcesExit, i1.WICExit,
        i1.LowIncomeHousingExit, i1.KidsCareExit, i1.AHCCCSExit, i1.CashAssistanceExit, i1.IncomeOtherExit,
        Leaver = CASE WHEN i1.ExitDate <= @EndDate THEN 1 ELSE 0 END,
        DV = CASE WHEN ivt.VictimTypeID = 5 THEN 1 ELSE 0 END
    FROM Participants p INNER JOIN Intakes i1 ON p.ParticipantID = i1.ParticipantID
        INNER JOIN LinkedIntakes li1 ON i1.IntakeID = li1.GainingIntakeID
        INNER JOIN Intakes i2 ON li1.OriginIntakeID = i2.IntakeID AND i2.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li2 ON i2.IntakeID = li2.GainingIntakeID
        LEFT OUTER JOIN Intakes i3 ON li2.OriginIntakeID = i3.IntakeID AND i3.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li3 ON i3.IntakeID = li3.GainingIntakeID
        LEFT OUTER JOIN Intakes i4 ON li3.OriginIntakeID = i4.IntakeID AND i4.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li4 ON i4.IntakeID = li4.GainingIntakeID
        LEFT OUTER JOIN Intakes i5 ON li4.OriginIntakeID = i5.IntakeID AND i5.IntakeTypeID = 2
        LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i1.IntakeID
    WHERE i1.IntakeTypeID = 2 AND i1.DeletedDate IS NULL AND
        i2.EntryDate <= @EndDate AND (i1.ExitDate IS NULL OR i1.ExitDate >= @StartDate)
    -- Single intake participants:  Not gained by or from another transitional intake
    UNION ALL
    SELECT p.ParticipantID, LastName + ', ' + FirstName AS ParticipantName,
        p.DOB, i.EntryDate, i.ExitDate, Bednights = 0, LOS = 0, Age = 0, Sex, EthnicityID, Veteran,
        i.MentalIllness, i.PhysDisability, i.DevDisability, i.HIVAIDS, i.SubstanceAbuseID, i.PriorResidenceID, Conditions = 0,
        NumberChildren = 
            (SELECT ISNULL(COUNT(ChildID), 0) FROM ChildIntakes ci
            WHERE ci.IntakeID = i.IntakeID AND ci.DeletedDate IS NULL),
        i.IncomeEntry, i.IncomeExit, i.ExitHousingID,
        i.SSI, i.SSDI, i.SS, i.GenPubAssistance, i.TANF, i.ChildSupport, i.VetBenefits, i.EmploymentIncome, i.UnemploymentBenefits,
        i.Medicare, i.Medicaid, i.FoodStamps, i.NoFinancialResources, i.WIC, i.LowIncomeHousing, i.KidsCare, i.AHCCCS, i.CashAssistance,
        i.IncomeOther, CashSourceEntry = 0, CashSourceExit = 0, NonCashSourceEntry = 0, NonCashSourceExit = 0,
            i.SSIExit, i.SSDIExit, i.SSExit, i.GenPubAssistanceExit, i.TANFExit, i.ChildSupportExit, i.VetBenefitsExit, i.EmploymentIncomeExit,
        i.UnemploymentBenefitsExit, i.MedicareExit, i.MedicaidExit, i.FoodStampsExit, i.NoFinancialResourcesExit, i.WICExit,
        i.LowIncomeHousingExit, i.KidsCareExit, i.AHCCCSExit, i.CashAssistanceExit, i.IncomeOtherExit,
        Leaver = CASE WHEN i.ExitDate <= @EndDate THEN 1 ELSE 0 END,
        DV = CASE WHEN ivt.VictimTypeID = 5 THEN 1 ELSE 0 END
    FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        LEFT OUTER JOIN Intakes i1 ON li.OriginIntakeID = i1.IntakeID AND i1.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li2 ON i.IntakeID = li2.OriginIntakeID
        LEFT OUTER JOIN Intakes i2 ON i2.IntakeID = li2.GainingIntakeID AND i2.IntakeTypeID = 2
        LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
    WHERE i1.IntakeID IS NULL AND i2.IntakeID IS NULL AND i.IntakeTypeID = 2 AND i.DeletedDate IS NULL
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    ORDER BY ParticipantName;

    -- Child Intakes that are gained from another transitional intake (continuation)
    SELECT c.ChildID, LastName + ', ' + FirstName + '*' AS ChildName, c.DOB,
        ISNULL(ci5.EntryDate, ISNULL(ci4.EntryDate, ISNULL(ci3.EntryDate, ci2.EntryDate))) AS EntryDate,
        i1.ExitDate, Age = 0, Sex, EthnicityID,
        ISNULL(ci5.SSI, ISNULL(ci4.SSI, ISNULL(ci3.SSI, ci2.SSI))) AS SSI,
  
      ISNULL(ci5.SSDI, ISNULL(ci4.SSDI, ISNULL(ci3.SSDI, ci2.SSDI))) AS SSDI,
        ISNULL(ci5.TANF, ISNULL(ci4.TANF, ISNULL(ci3.TANF, ci2.TANF))) AS TANF,
        ISNULL(ci5.WIC, ISNULL(ci4.WIC, ISNULL(ci3.WIC, ci2.WIC))) AS WIC,
        ISNULL(ci5.AHCCCS, ISNULL(ci4.AHCCCS, ISNULL(ci3.AHCCCS, ci2.AHCCCS))) AS AHCCCS,
        ISNULL(ci5.LowIncomeHousing, ISNULL(ci4.LowIncomeHousing, ISNULL(ci3.LowIncomeHousing, ci2.LowIncomeHousing))) AS LowIncomeHousing,
        ISNULL(ci5.KidsCare, ISNULL(ci4.KidsCare, ISNULL(ci3.KidsCare, ci2.KidsCare))) AS KidsCare,
        ISNULL(ci5.FoodStamps, ISNULL(ci4.FoodStamps, ISNULL(ci3.FoodStamps, ci2.FoodStamps))) AS FoodStamps,
        ISNULL(ci5.CashAssistance, ISNULL(ci4.CashAssistance, ISNULL(ci3.CashAssistance, ci2.CashAssistance))) AS CashAssistance,
        CashSourceEntry = 0, NonCashSourceEntry = 0,
        Leaver = CASE WHEN i1.ExitDate <= @EndDate THEN 1 ELSE 0 END
    FROM Children c INNER JOIN ChildIntakes ci1 ON c.ChildID = ci1.ChildID
        INNER JOIN Intakes i1 ON ci1.IntakeID = i1.IntakeID AND i1.IntakeTypeID = 2
        INNER JOIN LinkedIntakes li1 ON i1.IntakeID = li1.GainingIntakeID
        INNER JOIN Intakes i2 ON li1.OriginIntakeID = i2.IntakeID AND i2.IntakeTypeID = 2
        INNER JOIN ChildIntakes ci2 ON i2.IntakeID = ci2.IntakeID AND ci2.ChildID = c.ChildID
        LEFT OUTER JOIN LinkedIntakes li2 ON i2.IntakeID = li2.GainingIntakeID
        LEFT OUTER JOIN Intakes i3 ON li2.OriginIntakeID = i3.IntakeID AND i3.IntakeTypeID = 2
        LEFT OUTER JOIN ChildIntakes ci3 ON i3.IntakeID = ci3.IntakeID AND ci3.ChildID = c.ChildID
        LEFT OUTER JOIN LinkedIntakes li3 ON i3.IntakeID = li3.GainingIntakeID
        LEFT OUTER JOIN Intakes i4 ON li3.OriginIntakeID = i4.IntakeID AND i4.IntakeTypeID = 2
        LEFT OUTER JOIN ChildIntakes ci4 ON i4.IntakeID = ci4.IntakeID AND ci4.ChildID = c.ChildID
        LEFT OUTER JOIN LinkedIntakes li4 ON i4.IntakeID = li4.GainingIntakeID
        LEFT OUTER JOIN Intakes i5 ON li4.OriginIntakeID = i5.IntakeID AND i5.IntakeTypeID = 2
        LEFT OUTER JOIN ChildIntakes ci5 ON i5.IntakeID = ci5.IntakeID AND ci5.ChildID = c.ChildID
    WHERE i1.DeletedDate IS NULL AND ci1.DeletedDate IS NULL AND c.DeletedDate IS NULL
        AND i2.EntryDate <= @EndDate AND (i1.ExitDate IS NULL OR i1.ExitDate >= @StartDate)
    UNION ALL
    -- Single intake children
    SELECT c.ChildID, LastName + ', ' + FirstName AS ChildName,
        c.DOB, i.EntryDate, i.ExitDate, Age = 0, Sex, EthnicityID,
        ci.SSI, ci.SSDI, ci.TANF, ci.WIC, ci.AHCCCS, ci.LowIncomeHousing, ci.KidsCare, ci.FoodStamps, ci.CashAssistance,
        CashSourceEntry = 0,  NonCashSourceEntry = 0,
        Leaver = CASE WHEN i.ExitDate <= @EndDate THEN 1 ELSE 0 END
    FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID AND i.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li ON i.IntakeID = li.GainingIntakeID
        LEFT OUTER JOIN Intakes i1 ON li.OriginIntakeID = i1.IntakeID AND i1.IntakeTypeID = 2
        LEFT OUTER JOIN LinkedIntakes li2 ON i.IntakeID = li2.OriginIntakeID
        LEFT OUTER JOIN Intakes i2 ON i2.IntakeID = li2.GainingIntakeID AND i2.IntakeTypeID = 2
    WHERE i1.IntakeID IS NULL AND i2.IntakeID IS NULL AND i.IntakeTypeID = 2
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    ORDER BY ChildName;

rpt_InformationRelease
CREATE PROCEDURE dbo.rpt_InformationRelease
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	SELECT ir.ParticipantID, ir.ReleaseID, 
        NonCurrent = CAST(CASE WHEN i.IntakeID IS NULL THEN 1 ELSE 0 END AS BIT),
        p.LastName + ', ' + p.FirstName AS Participant, ir.FromDate, ir.ToDate,
        rt.ReleaseType, ie.Entity
    FROM Intakes i RIGHT OUTER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            AND @StartDate BETWEEN i.EntryDate AND ISNULL(i.ExitDate, @StartDate)
        INNER JOIN InfoReleases ir ON p.ParticipantID = ir.ParticipantID
        INNER JOIN ReleaseTypes rt ON ir.ReleaseTypeID = rt.ReleaseTypeID
        INNER JOIN ReleaseEntities re ON ir.ReleaseID = re.ReleaseID
        INNER JOIN InfoEntities ie ON re.EntityID = ie.EntityID
    WHERE @StartDate BETWEEN ir.FromDate AND ir.ToDate
        AND ir.DeletedDate IS NULL AND p.DeletedDate IS NULL
    ORDER BY Participant, FromDate, Entity;

rpt_IntakeData
CREATE PROCEDURE dbo.rpt_IntakeData
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	SELECT i.AbusedAsChild, i.AbuseEconomic, i.AbusePhysical, i.AbuseSexual, i.AbuseVerbalPsychological, i.AbuseWitness,
        i.TANF_Eligible, i.DevDisability, i.PhysDisability, i.MentalIllness, i.Pregnant, i.ChronicHealthCondition, i.HIVAIDS,
        s.ShelterName, x.IntakeType, i.ParticipantID, i.IntakeTypeID, i.ShelterID
    FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE EntryDate <= @EndDate AND (ExitDate IS NULL OR ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
    ORDER BY s.ShelterName, i.IntakeTypeID, i.ParticipantID, i.EntryDate;

rpt_LocationsServed
CREATE PROCEDURE dbo.rpt_LocationsServed
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT ShelterName, Location, LastName + ', ' + FirstName + ' ' + MI AS FullName, ISNULL(OptionalIdentifier, '') AS OptionalID,
        i.IntakeTypeID, IntakeType, ISNULL(i.NumberChildren, 0) AS NumberChildren, p.EthnicityID, Ethnicity, p.DOB, Employment, i.EntryDate,
        DATEDIFF(year, DOB, i.EntryDate) AS Age, s.ShelterID, xl.LocationID, xem.EmploymentID,
            ServiceHours =
            (
                SELECT ISNULL(SUM(SessionHours * NumberStaff), 0)
                FROM ClientSessions cs INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
                WHERE cs.ClientID = p.ParticipantID AND
                    cs.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.ClientTypeID = 1
                    AND s.SessionDate BETWEEN @StartDate AND @EndDate
            ),
            AccompanyingChildren =
            (
                SELECT ISNULL(COUNT(ChildID), 0)
                FROM ChildIntakes ci
                WHERE ci.IntakeID = i.IntakeID AND i.IntakeTypeID IN (1, 2, 3, 5)
                    AND ci.DeletedDate IS NULL
            ),
            Bednights = CASE
   	            WHEN i.IntakeTypeID IN (4, 6) THEN 0
	            WHEN i.EntryDate = i.ExitDate THEN 1
	            WHEN i.EntryDate BETWEEN @StartDate AND @EndDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
	            WHEN i.EntryDate BETWEEN @StartDate AND @EndDate AND i.ExitDate BETWEEN @StartDate AND @EndDate THEN DATEDIFF(day, i.EntryDate, i.ExitDate)
	            WHEN i.EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
	            WHEN i.EntryDate < @StartDate AND i.ExitDate BETWEEN @StartDate AND @EndDate THEN DATEDIFF(day, @StartDate, i.ExitDate)
                END
    FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
        INNER JOIN xEmployment xem ON i.EmploymentID = xem.EmploymentID
    WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
    ORDER BY ShelterName, Location, IntakeTypeID, FullName;

rpt_NavajoNation
CREATE PROCEDURE dbo.rpt_NavajoNation
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	-- Narratives
        SELECT
        A01 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-01'), ''),
        A02 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'A-02'), ''),
        Shelters =
            (SELECT COUNT(ShelterID)
            FROM Shelters
            WHERE Residential = 1 AND ShelterTypeID IN (1, 2)
                AND IsCurrent = 1 AND DeletedDate IS NULL),
        NonShelters =
            (SELECT COUNT(ShelterID)
            FROM Shelters
            WHERE Residential = 0 AND NonResidential = 1 AND ShelterTypeID = 1
                AND IsCurrent = 1 AND DeletedDate IS NULL),
        Volunteers = 0, Hours = 0.0; 
   -- Volunteer count and hours
        SELECT COUNT(s.StaffID) AS Volunteers, Hours =
            ((SELECT ISNULL(SUM(va.Hours), 0)
            FROM VolunteerActivity va INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
            WHERE vs.DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate)
            +
            (SELECT ISNULL(SUM(SessionHours), 0) FROM Sessions s INNER JOIN StaffSessions ss
            ON s.SessionID = ss.SessionID INNER JOIN Staff ON ss.StaffID = Staff.StaffID
            WHERE Staff.Status = 2 AND s.DeletedDate IS NULL AND Staff.DeletedDate IS NULL
                AND SessionDate BETWEEN @StartDate AND @EndDate))
        FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
        WHERE (se.HireDate IS NULL OR se.HireDate <= @EndDate)
            AND (s.DateLeft IS NULL OR s.DateLeft > @EndDate)
            AND s.DeletedDate IS NULL AND s.Status = 2; 

    -- Clients
    -- Resident and Non-resident information; duplicates (repeats) removed after table is retrieved
        SELECT p.ParticipantID AS ClientID, ClientTypeID = 1, p.Sex, p.DOB, i.EntryDate, Age = 0, p.EthnicityID, i.IntakeTypeID
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 2, 4)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
        UNION ALL
        SELECT c.ChildID AS ClientID, ClientTypeID = 2, c.Sex, c.DOB, ci.EntryDate, Age = 0, c.EthnicityID, i.IntakeTypeID
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 2, 4)
            AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        ORDER BY ClientTypeID, ClientID, IntakeTypeID, EntryDate;

    -- Bednights and Unmet Requests for Shelter (Section C)
        SELECT Bednights =
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN i.EntryDate = i.ExitDate THEN 1
                WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1 
                WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1 
                ELSE DateDiff(day, i.EntryDate, i.ExitDate) END) OVER () 
            FROM Intakes i  
            WHERE IntakeTypeID < 3 AND i.EntryDate BETWEEN @StartDate AND @EndDate
                AND i.DeletedDate IS NULL), 0)
            + 
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN EntryDate = ExitDate THEN 1
                WHEN ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                WHEN ExitDate > @EndDate THEN DATEDIFF(day, @StartDate , @EndDate) + 1
                ELSE DATEDIFF(day, @StartDate, ExitDate) END) OVER()
            FROM Intakes
            WHERE IntakeTypeID < 3 AND EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate >= @StartDate )
                AND DeletedDate IS NULL), 0)
            +
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END) OVER()
            FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            WHERE i.IntakeTypeID < 3 AND ci.EntryDate BETWEEN @StartDate AND @EndDate
                AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL), 0)
            +
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, + @StartDate, @EndDate) + 1
                WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END) OVER()
            FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            WHERE i.IntakeTypeID < 3 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate )
                AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL), 0)
            +
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
                WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
                ELSE DATEDIFF(day, DateReturn, DateOut) END) OVER()
            FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
                INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
            WHERE IntakeTypeID < 3 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate )
                AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND ca.DateOut BETWEEN @StartDate AND @EndDate), 0)
            +
            ISNULL(
            (SELECT TOP 1 SUM(CASE
                WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
                WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
                ELSE DATEDIFF(day, DateReturn, DateOut) END) OVER()
            FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
                INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
            WHERE IntakeTypeID < 3 AND ci.EntryDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
                AND ca.DateOut BETWEEN @StartDate AND @EndDate), 0),
        NoRoom =
            (SELECT COUNT(c.CallID)
            FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
            WHERE c.CallDate BETWEEN @StartDate AND @EndDate
                AND c.DeletedDate IS NULL
                AND c.CallSubjectID = 5 AND sr.ReasonDeniedID = 1); 

    -- Hotline calls (Section D1)
        SELECT COUNT(CallID) AS HotlineCalls
        FROM Calls
        WHERE CallDate BETWEEN @StartDate AND @EndDate
            AND DeletedDate IS NULL AND CallTypeID < 4 AND WalkIn = 0; 

    -- Narratives H-01 - H-06
        SELECT
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-01'), '') AS H01,
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-02'), '') AS H02,
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-03'), '') AS H03,
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND Rep
ortDate = @StartDate AND Item = 'H-04'), '') AS H04,
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-05'), '') AS H05,
            ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'H-06'), '') AS H06; 

    -- Services (Sections D, E, F)
        SELECT ClientTypeID = 1, cs.ClientID, s.SessionHours, sm.GrantorServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1
            INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID IN (701, 702) AND i.IntakeTypeID IN (1, 2, 4)
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
        UNION ALL
        SELECT ClientTypeID = 2, cs.ClientID, s.SessionHours, sm.GrantorServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 701 AND 704 AND i.IntakeTypeID IN (1, 2, 4)
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        UNION ALL
        SELECT ClientTypeID = 3, cs.ClientID, s.SessionHours, sm.GrantorServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 3
            INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate AND sm.GrantorServiceID IN (701, 702)
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND ai.DeletedDate IS NULL
        ORDER BY ClientTypeID, GrantorServiceID; 

    -- Presentations
        SELECT PresentationID, IsPresentation, YouthTargeted, NumberAttended
        FROM Presentations
        WHERE DeletedDate IS NULL AND
            PresentationDate BETWEEN @StartDate AND @EndDate; 

    -- Abusers
        SELECT a.AbuserID, a.Sex, a.DOB, ai.EntryDate, Age = 0
        FROM Abusers a INNER JOIN AbuserIntakes ai ON a.AbuserID = ai.AbuserID
        WHERE ai.EntryDate <= @EndDate AND
            (ai.ExitDate IS NULL OR ai.ExitDate >= @StartDate)
            AND a.DeletedDate IS NULL AND ai.DeletedDate IS NULL
        ORDER BY a.AbuserID, ai.EntryDate;

rpt_NewClients
-- Add StillInRelationShip table
CREATE PROCEDURE rpt_NewClients
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT p.ParticipantID AS ClientID, i.ShelterID, s.ShelterName, i.IntakeTypeID, ClientType = 0, p.DOB, p.Sex,
        p.LastName + ', ' + p.FirstName AS FullName, i.CountyID, i.LocationID,
        DATEDIFF(year, p.DOB, i.EntryDate) AS Age , p.EthnicityID, i.EntryDate, Location, County,
        LastNight = CASE
        WHEN i.ExitDate = i.EntryDate THEN DATEADD(DAY, 1, i.EntryDate)
        WHEN i.ExitDate IS NULL THEN DATEADD(DAY, 1, @EndDate)
        WHEN i.ExitDate > @EndDate THEN DATEADD(DAY, 1, @EndDate)
        ELSE i.ExitDate END,
        i.MentalIllness, i.PhysDisability, i.DevDisability, i.HIVAIDS, p.Veteran,
        i.EmploymentID, i.AbuserRelationshipID, x.AbuserRelationship, i.SubstanceAbuseID, i.IncomeEntry * 12 AS Income, 
        i.SSI, i.SSDI, i.SS, i.GenPubAssistance, TANF = CAST(CASE WHEN i.TANF = 1 OR i.CashAssistance = 1 THEN 1 ELSE 0 END AS BIT),
        i.ChildSupport, i.VetBenefits, i.UnemploymentBenefits, i.Medicare,
        Medicaid = CAST(CASE WHEN i.AHCCCS = 1 OR i.Medicaid = 1 THEN 1 ELSE 0 END AS BIT),
        i.FoodStamps, i.NoFinancialResources, i.WIC, i.LowIncomeHousing, i.KidsCare, i.EmploymentIncome, i.IncomeOther, LGBT = CAST(p.LGBT AS BIT)
    FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xAbuserRelationship x ON i.AbuserRelationshipID = x.AbuserRelationshipID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
        LEFT JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
    WHERE i.EntryDate BETWEEN @StartDate AND @EndDate AND ci.ChildID IS NULL
        AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
    UNION ALL
    -- Parents--intake has at least one associated child intake
    SELECT p.ParticipantID AS ClientID, i.ShelterID, s.ShelterName, i.IntakeTypeID, ClientType = 1, p.DOB, p.Sex,
        p.LastName + ', ' + p.FirstName AS FullName, i.CountyID, i.LocationID,
        DATEDIFF(year, p.DOB, i.EntryDate) AS Age , p.EthnicityID, i.EntryDate,  Location, County,
        LastNight = CASE
        WHEN i.ExitDate = i.EntryDate THEN DATEADD(DAY, 1, i.EntryDate)
        WHEN i.ExitDate IS NULL THEN DATEADD(DAY, 1, @EndDate)
        WHEN i.ExitDate > @EndDate THEN DATEADD(DAY, 1, @EndDate)
        ELSE i.ExitDate END,
        i.MentalIllness, i.PhysDisability, i.DevDisability, i.HIVAIDS, p.Veteran,
        i.EmploymentID, i.AbuserRelationshipID, x.AbuserRelationship, i.SubstanceAbuseID, i.IncomeEntry * 12 AS Income, 
        i.SSI, i.SSDI, i.SS, i.GenPubAssistance, TANF = CAST(CASE WHEN TANF = 1 OR CashAssistance = 1 THEN 1 ELSE 0 END AS BIT),
        i.ChildSupport, i.VetBenefits, i.UnemploymentBenefits, i.Medicare,
        Medicaid = CAST(CASE WHEN AHCCCS = 1 OR Medicaid = 1 THEN 1 ELSE 0 END AS BIT),
        i.FoodStamps, i.NoFinancialResources, i.WIC, i.LowIncomeHousing, i.KidsCare, i.EmploymentIncome, i.IncomeOther, LGBT = CAST(p.LGBT AS BIT)
    FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xAbuserRelationship x ON i.AbuserRelationshipID = x.AbuserRelationshipID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
    WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
        AND  (SELECT COUNT(IntakeID) FROM ChildIntakes WHERE IntakeID = i.IntakeID
        AND DeletedDate IS NULL) > 0
    UNION ALL
    -- New Children
    SELECT c.ChildID AS ClientID, i.ShelterID, s.ShelterName, i.IntakeTypeID, ClientType = 2, c.DOB, c.Sex,
        c.LastName + ', ' + c.FirstName AS FullName, i.CountyID, i.LocationID,
        DATEDIFF(year, c.DOB, ci.EntryDate) AS Age, c.EthnicityID, ci.EntryDate,  Location, County,
        LastNight = CASE
        WHEN ci.ExitDate = ci.EntryDate THEN DATEADD(day, 1, ci.ExitDate)
        WHEN ci.ExitDate IS NULL THEN DATEADD(day, 1, @EndDate)
        WHEN ci.ExitDate > @EndDate THEN DATEADD(day, 1, @EndDate)
        ELSE ci.ExitDate END,
        ci.MentalIllness, ci.PhysDisability, ci.DevDisability, ci.HIVAIDS,
        Veteran = 0, EmploymentID = 0, AbuserRelationshipID = 0, AbuserRelationship = '', ci.SubstanceAbuseID, Income = 0,
        ci.SSI, ci.SSDI, SS = 0, GenPubAssistance = 0, TANF = CAST(CASE WHEN ci.TANF = 1 OR ci.CashAssistance = 1 THEN 1 ELSE 0 END AS BIT),
        ChildSupport = 0, VetBenefits = 0, UnemploymentBenefits = 0, Medicare = 0, ci.AHCCCS AS Medicaid,
        ci.FoodStamps, NoFinancialResources = 0, ci.WIC, ci.LowIncomeHousing, ci.KidsCare, EmploymentIncome = 0, IncomeOther = '', LGBT = CAST(0 AS BIT)
    FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN Shelters s ON s.ShelterID = i.ShelterID
        INNER JOIN xCounty xc ON i.CountyID = xc.CountyID
        INNER JOIN xLocation xl ON i.LocationID = xl.LocationID
    WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
        AND ci.DeletedDate IS NULL AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL
    ORDER BY i.ShelterID, i.IntakeTypeID,  ClientType;
    SELECT c.ShelterID, ShelterName, c.CallSubjectID, CallSubject, CallTypeID,
        c.LocationID, xl.Location, c.NumberChildren, c.Turnaway,
        ShelterRequest = CAST(CASE WHEN sr.CallID IS NULL THEN 0 ELSE 1 END AS BIT),
        ISNULL(sr.RequestOutcomeID, -1) AS RequestOutcomeID, 
        ISNULL(sr.ReasonDeniedID, -1) AS ReasonDeniedID,
        ISNULL(RequestOutcome, 'N/A') AS RequestOutcome,
        ISNULL(ReasonDenied, 'N/A') AS ReasonDenied,
        ISNULL(i.IntakeTypeID, 0) AS IntakeTypeID
    FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
        INNER JOIN xCallSubject xcs ON c.CallSubjectID = xcs.CallSubjectID
        INNER JOIN xLocation xl ON c.LocationID = xl.LocationID
        LEFT OUTER JOIN ShelterRequests sr on c.CallID = sr.CallID
        LEFT OUTER JOIN xReasonDenied xrd ON sr.ReasonDeniedID = xrd.ReasonDeniedID
        LEFT OUTER JOIN xRequestOutcome xro ON sr.RequestOutcomeID = xro.RequestOutcomeID
        LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
        LEFT OUTER JOIN Intakes i ON ic.IntakeID = i.IntakeID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate AND c.DeletedDate IS NULL AND c.CallTypeID < 4 
    ORDER BY ShelterID;
	SELECT s.ShelterName, i.StillInRelationship, i.ParticipantID
	FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
	WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
		AND i.StillInRelationship = 1
	ORDER BY s.ShelterName;

rpt_ParticipantRoster
CREATE PROCEDURE dbo.rpt_ParticipantRoster
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT p.ParticipantID, LastName, FirstName, MI, OptionalIdentifier, DOB, ReturnStatus, Resident = 1,
        p.ReturnStatusID, i.IntakeTypeID, i.CountyID, i.LocationID, p.EthnicityID, i.ShelterID 
    FROM Participants p INNER JOIN xReturnStatus xrs ON xrs.ReturnStatusID = p.ReturnStatusID
        INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR I.ExitDate >= @StartDate)
        AND i.IntakeTypeID IN (1, 2, 3, 5)
    UNION ALL
    SELECT p.ParticipantID, LastName, FirstName, MI, OptionalIdentifier, DOB, ReturnStatus, Resident = 0,
        p.ReturnStatusID, i.IntakeTypeID, i.CountyID, i.LocationID, p.EthnicityID, i.ShelterID 
    FROM Participants p INNER JOIN xReturnStatus xrs ON xrs.ReturnStatusID = p.ReturnStatusID
        INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
    WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR I.ExitDate >= @StartDate)
        AND i.IntakeTypeID IN (4, 6)
    ORDER BY Resident DESC, LastName, FirstName, MI;

rpt_PermanentSafeHousing
CREATE PROCEDURE dbo.rpt_PermanentSafeHousing
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	DECLARE @TotalIntakes INT, @Children INT
    SELECT @TotalIntakes = COUNT(IntakeID)
    FROM Intakes
    WHERE IntakeTypeID < 3 AND DeletedDate IS NULL
        AND ExitDate BETWEEN @StartDate AND @EndDate
    -- Get count of all children with Crisis exits
    SELECT @Children = COUNT(ci.ChildIntakeID) 
    FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
    WHERE IntakeTypeID < 3 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        AND i.ExitDate BETWEEN @StartDate AND @EndDate
    -- Exit Destination
    SELECT @TotalIntakes AS TotalIntakes, TotalClients = @TotalIntakes + @Children, IntakeID,
        ISNULL(i.ExitDestinationID, 0) + 1 AS ExitID, ISNULL(xd.ExitDestination, 'Not Entered') AS ExitDescription, i.ShelterID, s.ShelterName,
        ExitStatus = CASE
            WHEN i.PermanentSafeHousing IS NULL THEN -1
            ELSE i.PermanentSafeHousing END,
        Clients = 1 +
        (SELECT COUNT(ChildIntakeID)
        FROM ChildIntakes ci
        WHERE ci.IntakeID = i.IntakeID AND DeletedDate IS NULL)
    FROM Intakes i LEFT OUTER JOIN xExitDestination xd ON i.ExitDestinationID = xd.ExitDestinationID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
    WHERE IntakeTypeID < 3 AND i.DeletedDate IS NULL
        AND ExitDate BETWEEN @StartDate AND @EndDate
    UNION ALL
    -- Exit Housing
    SELECT @TotalIntakes, TotalClients = @TotalIntakes + @Children, IntakeID,
        ISNULL(i.ExitHousingID, 0) + 1001 AS ExitID, ISNULL(xh.ExitHousing, 'Not Entered') AS ExitDescription, i.ShelterID, s.ShelterName,
        ExitStatus = CASE
            WHEN i.PermanentSafeHousing IS NULL THEN -1
            ELSE i.PermanentSafeHousing END,
        Clients = 1 +
        (SELECT COUNT(ChildIntakeID)
        FROM ChildIntakes ci
        WHERE ci.IntakeID = i.IntakeID AND DeletedDate IS NULL)
    FROM Intakes i LEFT OUTER JOIN xExitHousing xh ON i.ExitHousingID = xh.ExitHousingID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
    WHERE IntakeTypeID < 3 AND i.DeletedDate IS NULL
        AND ExitDate BETWEEN @StartDate AND @EndDate
    ORDER BY ShelterName, ExitStatus, ExitID;

rpt_PetRoster
CREATE PROCEDURE dbo.rpt_PetRoster
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT pp.LastName + ', ' + pp.FirstName AS Participant,
        p.Name, x.PetType, p.Breed, p.IsAbused, p.IsVaccinated
    FROM Pets p INNER JOIN Intakes i ON p.IntakeID = i.IntakeID
        INNER JOIN xPetType x ON p.PetTypeID = x.PetTypeID
        INNER JOIN Participants pp ON i.ParticipantID = pp.ParticipantID
    WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND pp.DeletedDate IS NULL AND i.DeletedDate IS NULL
    ORDER BY Participant;

rpt_PhaseStatus
CREATE PROCEDURE dbo.rpt_PhaseStatus
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT CampusName, ShelterName, p.ParticipantID, ClientType = 1, s.ShelterID,
    p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName, p.Sex, p.OptionalIdentifier,
        p.DOB, ISNULL(b.Description, '') AS Bed, ISNULL(Phases.PhaseName, 'No Assigned Phase') AS Phase,
        ip.BeginDate, ip.ProjectedEnd, ISNULL(Phases.ProjectedLength, 0) AS ProjectedLength,
        i.IntakeTypeID, i.EntryDate, ISNULL(st.FirstName + ' ' + LEFT(st.LastName, 1), '') AS StaffName,
        ISNULL(ist.StaffRole, '') AS StaffRole
    FROM Campuses ca INNER JOIN Shelters s ON ca.CampusID = s.CampusID
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        LEFT OUTER JOIN IntakePhase ip ON i.IntakeID = ip.IntakeID
            AND @StartDate >= ip.BeginDate AND @StartDate < ISNULL(ip.CompletedDate, '6/6/2079')
        LEFT OUTER JOIN Phases ON ip.PhaseID = Phases.PhaseID
        LEFT OUTER JOIN IntakeBeds ib ON i.IntakeID = ib.IntakeID AND ib.DeletedDate IS NULL
            AND ib.ClientTypeID = 1 AND @StartDate >= ib.DateIn AND @StartDate < ISNULL(ib.DateOut, '6/6/2079')
        LEFT OUTER JOIN Beds b ON ib.BedID = b.BedID
        LEFT OUTER JOIN IntakeStaff ist ON i.IntakeID = ist.IntakeID
        LEFT OUTER JOIN Staff st ON st.StaffID = ist.StaffID
    WHERE @StartDate BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/6/2079')
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION
    SELECT CampusName, ShelterName, c.ParticipantID, ClientType = 2, s.ShelterID, 
    c.LastName + ', ' + c.FirstName + ' ' + c.MI AS FullName, c.Sex, OptionalIdentifier = '',
        c.DOB, ISNULL(b.Description, '') AS Bed, ISNULL(Phases.PhaseName, 'No Assigned Phase') AS Phase, 
        ip.BeginDate, ip.ProjectedEnd, ProjectedLength = 0, i.IntakeTypeID, ci.EntryDate, StaffName = '', StaffRole = ''
    FROM Campuses ca INNER JOIN Shelters s ON ca.CampusID = s.CampusID
        INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
        INNER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
        LEFT OUTER JOIN IntakePhase ip ON i.IntakeID = ip.IntakeID
            AND @StartDate >= ip.BeginDate AND @StartDate < ISNULL(ip.CompletedDate, '6/6/2079')
        LEFT OUTER JOIN Phases ON ip.PhaseID = Phases.PhaseID
        LEFT OUTER JOIN IntakeBeds ib ON ci.ChildIntakeID = ib.IntakeID AND ib.DeletedDate IS NULL
            AND ib.ClientTypeID = 2 AND @StartDate >= ib.DateIn AND @StartDate < ISNULL(ib.DateOut, '6/6/2079')
        LEFT OUTER JOIN Beds b ON ib.BedID = b.BedID
    WHERE @StartDate BETWEEN ci.EntryDate AND ISNULL(ci.ExitDate, '6/6/2079')
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND c.DeletedDate IS NULL
    ORDER BY CampusName, ShelterName, Phase, IntakeTypeID, ParticipantID, ClientType, FullName, StaffRole, StaffName;

rpt_ReferralAgencies
-- Stored procedure for new report, Referral Agencies
CREATE PROCEDURE dbo.rpt_ReferralAgencies
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	SELECT r.Agency, SUM(r.NumberReferrals) AS Referrals
	FROM Referrals r	
	WHERE ReferralDate BETWEEN @StartDate AND @EndDate
		AND r.DeletedDate IS NULL
	GROUP BY Agency
	ORDER BY Agency

rpt_ReferralsByStaff
CREATE PROCEDURE dbo.rpt_ReferralsByStaff
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT s.StaffID, LastName + ', ' + FirstName + ' ' + MI AS FullName, NumberReferrals, r.ReferralTypeID, ReferralType
    FROM Staff s INNER JOIN StaffReferrals sr ON s.StaffID = sr.StaffID
        INNER JOIN Referrals r ON sr.ReferralID = r.ReferralID
        INNER JOIN xReferralType x ON x.ReferralTypeID = r.ReferralTypeID
    WHERE s.DeletedDate IS NULL AND r.DeletedDate IS NULL
        AND r.ReferralDate BETWEEN @StartDate AND @EndDate
    ORDER BY FullName, ReferralType;

rpt_ReferralsByType
CREATE PROCEDURE dbo.rpt_ReferralsByType
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT r.ReferralID, r.ReferralTypeID, x.ReferralType, r.ReferralDate, r.NumberReferrals,
        r.ClientTypeID, p.LastName + ', ' + p.FirstName + ' (P)' AS Client,
        ISNULL(s.LastName + ', ' + s.FirstName, '') AS Staff
    FROM Referrals r INNER JOIN Participants p ON r.ClientID = p.ParticipantID AND r.ClientTypeID = 1
        INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
        LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
        LEFT OUTER JOIN Staff s ON sr.StaffID = s.StaffID
    WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
        AND r.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    SELECT r.ReferralID, r.ReferralTypeID, x.ReferralType, r.ReferralDate, r.NumberReferrals,
        r.ClientTypeID, c.LastName + ', ' + c.FirstName + ' (C)' AS Client,
        ISNULL(s.LastName + ', ' + s.FirstName, '') AS Staff
    FROM Referrals r INNER JOIN Children c ON r.ClientID = c.ChildID AND r.ClientTypeID = 2
        INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
        LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
        LEFT OUTER JOIN Staff s ON sr.StaffID = s.StaffID
    WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
        AND r.DeletedDate IS NULL AND c.DeletedDate IS NULL
    UNION ALL
    SELECT r.ReferralID, r.ReferralTypeID, x.ReferralType, r.ReferralDate, r.NumberReferrals,
        r.ClientTypeID, a.LastName + ', ' + a.FirstName + ' (A)' AS Client,
        ISNULL(s.LastName + ', ' + s.FirstName, '') AS Staff
    FROM Referrals r INNER JOIN Abusers a ON r.ClientID = a.AbuserID AND r.ClientTypeID = 3
        INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
        LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
        LEFT OUTER JOIN Staff s ON sr.StaffID = s.StaffID
    WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
        AND r.DeletedDate IS NULL AND a.DeletedDate IS NULL
    UNION ALL
    SELECT r.ReferralID, r.ReferralTypeID, x.ReferralType, r.ReferralDate, r.NumberReferrals,
        r.ClientTypeID, m.LastName + ', ' + m.FirstName + ' (M)' AS Client,
        ISNULL(s.LastName + ', ' + s.FirstName, '') AS Staff
    FROM Referrals r INNER JOIN CommunityMembers m ON r.ClientID = m.MemberID AND r.ClientTypeID = 4
        INNER JOIN xReferralType x ON r.ReferralTypeID = x.ReferralTypeID
        LEFT OUTER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
        LEFT OUTER JOIN Staff s ON sr.StaffID = s.StaffID
    WHERE r.ReferralDate BETWEEN @StartDate AND @EndDate
        AND r.DeletedDate IS NULL AND m.DeletedDate IS NULL
    ORDER BY x.ReferralType, r.ReferralDate, r.ClientTypeID, Client;

rpt_ReferralSources
CREATE PROCEDURE dbo.rpt_ReferralSources
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT i.ShelterID, s.ShelterName, x.ReferralSource, i.ReferralSourceID, i.IntakeTypeID,
        IsNew = CAST(CASE 
        WHEN i.EntryDate >= @StartDate THEN 1 ELSE 0 END AS BIT)
    FROM Intakes i INNER JOIN xReferralSource x ON i.ReferralSourceID = x.ReferralSourceID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
    WHERE i.DeletedDate IS NULL AND
        i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
    ORDER BY ShelterName, ReferralSource, IsNew DESC;

rpt_RepeatParticipants
CREATE PROCEDURE dbo.rpt_RepeatParticipants
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT ClientType = 1, p.ParticipantID AS ClientID, LastName + ', ' + FirstName + ' ' + MI AS FullName,
        i2.EntryDate, i2.ExitDate, i1.EntryDate AS CurrentEntry, i1.ExitDate AS CurrentExit, 
        s1.ShelterName AS CurrentShelter, s2.ShelterName AS PriorShelter,  Parent = '' 
    FROM Participants p INNER JOIN Intakes i1 ON p.ParticipantID = i1.ParticipantID
        INNER JOIN Intakes i2 ON i1.ParticipantID = i2.ParticipantID
        INNER JOIN Shelters s2 ON i2.ShelterID = s2.ShelterID
        INNER JOIN Shelters s1 ON i1.ShelterID = s1.ShelterID
    WHERE p.DeletedDate IS NULL AND i1.DeletedDate IS NULL AND i2.ExitDate IS NOT NULL AND i2.DeletedDate IS NULL
    AND i1.IntakeID <> i2.IntakeID AND 
        i1.EntryDate <= @EndDate AND (i1.ExitDate IS NULL OR i1.ExitDate >= @StartDate) AND
        i2.ExitDate <= i1.EntryDate
    UNION ALL
    SELECT ClientType = 2, c.ChildID AS ClientID, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS FullName,
        ci2.EntryDate, ci2.ExitDate, ci1.EntryDate AS CurrentEntry, ci1.ExitDate AS CurrentExit,
        CurrentShelter =
        (SELECT TOP 1 ShelterName
         FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
         WHERE i.IntakeID = ci1.IntakeID),
        PriorShelter =
        (SELECT TOP 1 ShelterName
         FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
         WHERE i.IntakeID = ci2.IntakeID ),
        Parent = 
        (SELECT TOP 1 LastName + ', ' + FirstName + ' ' + MI 
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        WHERE i.IntakeID = ci1.IntakeID)
    FROM Children c INNER JOIN ChildIntakes ci1 ON c.ChildID = ci1.ChildID
        INNER JOIN ChildIntakes ci2 ON c.ChildID = ci2.ChildID
    WHERE c.DeletedDate IS NULL AND ci1.DeletedDate IS NULL AND ci2.DeletedDate IS NULL
        AND ci1.ChildIntakeID <> ci2.ChildIntakeID AND
        ci1.EntryDate <= @EndDate AND (ci1.ExitDate IS NULL OR ci1.ExitDate >= @StartDate) AND
        ci2.ExitDate <= ci1.EntryDate
    ORDER BY ClientType, FullName;

rpt_ResidentCountByDay
CREATE PROCEDURE dbo.rpt_ResidentCountByDay
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Resident Participants (except Other)
    SELECT ShelterName, ParticipantID as ClientID, EntryDate, ExitDate, ClientTypeID = 1
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
    WHERE i.IntakeTypeID < 4 And i.EntryDate <= @EndDate And (i.ExitDate Is Null Or i.ExitDate >= @StartDate)
    AND i.DeletedDate IS NULL
    -- Resident Children (except Other)
    UNION ALL
    SELECT ShelterName, ChildID as ClientID, ci.EntryDate, ci.ExitDate, ClientTypeID = 2
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
    INNER JOIN ChildIntakes ci ON ci.IntakeID = i.IntakeID
    WHERE i.IntakeTypeID < 4 And ci.EntryDate <= @EndDate And (ci.ExitDate Is Null Or ci.ExitDate >= @StartDate)
    AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
    -- Other intakes:  IntakeTypeID == 5
    -- Other Participants
    UNION ALL
    SELECT ShelterName, ParticipantID as ClientID, EntryDate, ExitDate, ClientTypeID = 3
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
    WHERE i.IntakeTypeID = 5 And i.EntryDate <= @EndDate And (i.ExitDate Is Null Or i.ExitDate >= @StartDate)
    AND i.DeletedDate IS NULL
    -- Other Children
    UNION ALL
    SELECT ShelterName, ChildID as ClientID, ci.EntryDate, ci.ExitDate, ClientTypeID = 3
    FROM Shelters s INNER JOIN Intakes i ON s.ShelterID = i.ShelterID
    INNER JOIN ChildIntakes ci ON ci.IntakeID = i.IntakeID
    WHERE i.IntakeTypeID = 5 And ci.EntryDate <= @EndDate And (ci.ExitDate Is Null Or ci.ExitDate >= @StartDate)
    AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
    ORDER BY ShelterName, ClientTypeID, EntryDate;

rpt_RhbaParticipants
CREATE PROCEDURE rpt_RhbaParticipants
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	SELECT p.LastName + ', ' + p.FirstName AS Participant, i.EntryDate, i.ExitDate, r.* 
	FROM RHBA r INNER JOIN Participants p ON r.ParticipantID = p.ParticipantID
		INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
	WHERE p.DeletedDate IS NULL AND i.DeletedDate IS NULL
		AND i.EntryDate <= @EndDate
		AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
	ORDER BY Participant

rpt_RhbaServices
CREATE PROCEDURE dbo.rpt_RhbaServices
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT ss.SessionID, p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS FullName, DOB, IsNull(CisID, 0) AS CisID,
        ServiceName, IsNull(Diagnosis, '') AS Diagnosis, SessionDate, SessionHours, IsNull(DiagnosticCode, '') AS DiagnosticCode,
        ISNULL(st.LastName + ', ' + st.FirstName + ' ' + st.MI, '') AS StaffName, AhcccsID
    FROM RHBA r INNER JOIN Participants p ON r.ParticipantID = p.ParticipantID
        INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND ClientTypeID = 1
        INNER JOIN [Sessions] ss ON cs.SessionID = ss.SessionID
        INNER JOIN Services s ON ss.ServiceID = s.ServiceID
        LEFT OUTER JOIN StaffSessions sss ON ss.SessionID = sss.SessionID
        LEFT OUTER JOIN Staff st ON st.StaffID = sss.StaffID
    WHERE p.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND ss.DeletedDate IS NULL
        AND SessionDate BETWEEN @StartDate AND @EndDate
    ORDER BY FullName, SessionDate, SessionID;

rpt_RSHN
CREATE PROCEDURE dbo.rpt_RSHN
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	-- Item 5 Capacity (Residential shelters)
		SELECT HousingTypeID = 1, ISNULL(COUNT(b.BedID), 0) AS Beds
		FROM Shelters s INNER JOIN Beds b ON s.ShelterID = b.ShelterID AND s.HousingTypeID = 1
		WHERE s.IsCurrent = 1 AND b.IsCrib = 0 AND s.ShelterTypeID = 1
			AND b.DeletedDate IS NULL AND s.DeletedDate IS NULL
			AND b.ServiceStart <= @EndDate AND (b.ServiceEnd IS NULL OR b.ServiceEnd >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 2, COUNT(i.IntakeID) AS Beds
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 2
		WHERE s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL 
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 2, COUNT(ci.IntakeID) AS Beds
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 2
		WHERE s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 3, COUNT(i.IntakeID) AS Beds
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 3
		WHERE s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL 
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 3, COUNT(ci.IntakeID) AS Beds
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Shelters s ON i.ShelterID = s.ShelterID AND s.HousingTypeID = 3
		WHERE  s.ShelterTypeID = 1 AND s.IsCurrent = 1 AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
		UNION ALL
		SELECT HousingTypeID = 4, COUNT(r.RoomID)
		FROM Shelters s INNER JOIN Rooms r ON s.ShelterID = r.ShelterID
		WHERE s.IsCurrent = 1 AND s.ShelterTypeID = 2
			AND r.DeletedDate IS NULL AND s.DeletedDate IS NULL
			AND r.ServiceStart <= @EndDate AND (r.ServiceEnd IS NULL OR r.ServiceEnd >= @StartDate);

	-- Item 7 Program Staff
		SELECT Status, COUNT(s.StaffID) AS NumberStaff, Hours = 0
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID 
		WHERE (se.HireDate IS NULL Or se.HireDate <= @EndDate)
			And (s.DateLeft IS NULL Or s.DateLeft > @EndDate )
			And s.DeletedDate IS NULL And Status BETWEEN 0 And 1
		GROUP BY Status
		UNION ALL
		SELECT Status, COUNT(s.StaffID) AS NumberStaff, Hours =
			((SELECT ISNULL(SUM(va.Hours), 0)
			FROM VolunteerActivity va INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
			WHERE vs.DeletedDate IS NULL And ActivityDate BETWEEN @StartDate AND @EndDate)
			+
			(SELECT ISNULL(SUM(SessionHours), 0) FROM Sessions s INNER JOIN StaffSessions ss
			ON s.SessionID = ss.SessionID INNER JOIN Staff ON ss.StaffID = Staff.StaffID WHERE
			Staff.Status = 2 And s.DeletedDate IS NULL And Staff.DeletedDate IS NULL
				And SessionDate BETWEEN @StartDate AND @EndDate))
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
		WHERE (se.HireDate IS NULL Or se.HireDate <= @EndDate)
			And (s.DateLeft IS NULL Or s.DateLeft > @EndDate )
			And s.DeletedDate IS NULL And Status = 2
		GROUP BY Status

		UNION ALL
		SELECT Status = 2, OneTimeVolunteers, OneTimeHours * OneTimeVolunteers
		FROM VolunteerActivities
		WHERE DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate

		UNION ALL SELECT Status = 0, NumberStaff = 0, Hours = 0
		UNION ALL SELECT Status = 1, NumberStaff = 0, Hours = 0
		UNION ALL SELECT Status = 2, NumberStaff = 0, Hours = 0

		-- Block added to SUBTRACT volunteers on staff who had no activities or service sessions
		-- during the report period
		UNION ALL
		SELECT s.Status, -1 * COUNT(s.StaffID) AS NumberStaff, Hours = 0
		FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
			LEFT OUTER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
			LEFT OUTER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
		WHERE s.Status = 2 And s.DeletedDate IS NULL AND
			(se.HireDate IS NULL Or se.HireDate <= @EndDate) AND
			(s.DateLeft IS NULL Or s.DateLeft > @EndDate ) AND
			(ss.StaffID IS NULL AND va.StaffID IS NULL)
		GROUP BY Status
		ORDER BY Status;

	-- Item 7 Staff Training
		SELECT st.StaffID, ts.SessionID, ts.SessionHours
		FROM TrainingSessions ts INNER JOIN StaffTraining st ON ts.SessionID = st.SessionID
			INNER JOIN Staff s ON st.StaffID = s.StaffID AND s.DeletedDate IS NULL
		WHERE ts.SessionDate BETWEEN @StartDate AND @EndDate AND ts.DeletedDate IS NULL;

	-- Item New Client Demographics (DV victims only:  Crisis, Transitional, Non-Resident DV)
	-- Resident and Non-resident information; don't count repeats of the same type intake
		SELECT p.ParticipantID AS ClientID, ClientTypeID = 1, p.Sex, p.DOB, i.EntryDate, Age = 0, p.EthnicityID, i.IntakeTypeID
		FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
		WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 2, 4)
			AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
		UNION ALL
		SELECT c.ChildID AS ClientID, ClientTypeID = 2, c.Sex, c.DOB, ci.EntryDate, Age = 0, c.EthnicityID, i.IntakeTypeID
		FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID IN (1, 2, 4)
			AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
		ORDER BY ClientTypeID, ClientID, IntakeTypeID, EntryDate;

	-- Item 10 Bednights
	-- Bednights
		SELECT Bednights = CASE
			WHEN i.EntryDate = i.ExitDate THEN 1
			WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
			ELSE DateDiff(day, i.EntryDate, i.ExitDate) END
		FROM Intakes i WHERE IntakeTypeID = 1 AND i.EntryDate BETWEEN @StartDate AND @EndDate
			AND i.DeletedDate IS NULL
		UNION ALL
		SELECT Bednights = CASE
			WHEN EntryDate = ExitDate THEN 1
			WHEN ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			WHEN ExitDate > @EndDate THEN DATEDIFF(day, @StartDate , @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, ExitDate) END
		FROM Intakes
		WHERE IntakeTypeID = 1 AND EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate >= @StartDate )
			AND DeletedDate IS NULL
		UNION ALL
		SELECT Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
			ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		WHERE i.IntakeTypeID = 1 AND ci.EntryDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
		UNION ALL
		SELECT Bednights = CASE
			WHEN ci.EntryDate = ci.ExitDate THEN 1
			WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, + @StartDate, @EndDate) + 1
			WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
			ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		WHERE i.IntakeTypeID = 1 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate )
			AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
		UNION ALL
		SELECT Absences = CASE
			WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
			WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
			ELSE DATEDIFF(day, DateReturn, DateOut) EN
D
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
		WHERE IntakeTypeID = 1 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate )
			AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND ca.DateOut BETWEEN @StartDate AND @EndDate
		UNION ALL
		SELECT Absences = CASE
			WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
			WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
			ELSE DATEDIFF(day, DateReturn, DateOut) END
		FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
		WHERE IntakeTypeID = 1 AND ci.EntryDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
			AND ca.DateOut BETWEEN @StartDate AND @EndDate;

	-- Item 11 Reasons Shelter Not Provided
		SELECT c.CallID, c.NumberChildren, x.ReasonDenied, ReasonID = CASE
			WHEN sr.RequestOutcomeID = 7 THEN 100
			ELSE sr.ReasonDeniedID END
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID AND c.DeletedDate IS NULL
			INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
				AND c.CallSubjectID = 5 AND RequestOutcomeID IN (1, 7)
		ORDER BY ReasonID;

	-- Item 11 Other Reasons Shelter Denied -- Other
		SELECT x.ReasonDenied + ' (' + CAST(COUNT(x.ReasonDeniedID) AS VARCHAR) + ')' AS ReasonDenied
		FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID AND c.DeletedDate IS NULL
			INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
		WHERE c.CallDate BETWEEN @StartDate AND @EndDate
			AND CallSubjectID = 5 AND RequestOutcomeID IN (1, 7)
			AND (sr.ReasonDeniedID IN (2, 6, 9, 10) OR sr.ReasonDeniedID > 100)
		GROUP BY x.ReasonDenied ORDER BY x.ReasonDenied;
	-- Item 11 Length-of-Stay and Destination of Clients who exited
		SELECT DATEDIFF(day, i.EntryDate, i.ExitDate) AS Bednights, ISNULL(i.ExitDestinationID, 8) AS ExitDestinationID,
			HousingTypeID = CASE WHEN i.IntakeTypeID = 2 THEN 4 ELSE s.HousingTypeID END,
			Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID)
		FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
		WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID < 3
			AND i.DeletedDate IS NULL;

	-- Item 11 Other Exit destinations
		SELECT x.ExitDestination + ' (' + CAST(COUNT(x.ExitDestination) AS VARCHAR) + ')' AS ExitDestination
		FROM Intakes i INNER JOIN xExitDestination x ON i.ExitDestinationID = x.ExitDestinationID
		WHERE i.ExitDate BETWEEN @StartDate AND @EndDate
			AND i.IntakeTypeID = 1
			AND i.ExitDestinationID > 8
			AND i.DeletedDate IS NULL
		GROUP BY x.ExitDestination
		ORDER BY ExitDestination;

	-- Item 12 Hotline calls
		SELECT COUNT(CallID) AS HotlineCalls
		FROM Calls
		WHERE CallDate BETWEEN @StartDate AND @EndDate
			AND DeletedDate IS NULL AND CallTypeID < 4 AND WalkIn = 0;

	-- Items 13/14/15 Services to Clients, Children, Batterers
		-- From Participants, including Youth/IPV primary clients
		SELECT cs.ClientTypeID, cs.ClientID, s.SessionHours, sm.GrantorServiceID,
			Age = 0, p.DOB, i.EntryDate
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
			INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
		WHERE cs.ClientTypeID = 1 AND s.SessionDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorServiceID BETWEEN 401 AND 404
			AND i.IntakeTypeID IN (1, 2, 4) ---- Crisis, Non-Resident DV 
			AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
		UNION ALL
		-- From Children; add 1000000 to ClientID to keep it unique from ParticipantIDs
		SELECT cs.ClientTypeID, cs.ClientID + 1000000 AS ClientID, s.SessionHours, sm.GrantorServiceID,
			Age = 0, c.DOB, ci.EntryDate
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
			INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
			INNER JOIN Children c ON ci.ChildID = c.ChildID
		WHERE cs.ClientTypeID = 2 AND s.SessionDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorServiceID BETWEEN 401 AND 404
			AND i.IntakeTypeID IN (1, 2, 4) ---- Crisis, Non-Resident DV 
			AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
		UNION ALL
		-- Abusers
		SELECT cs.ClientTypeID, cs.ClientID, s.SessionHours, sm.GrantorServiceID,
			Age = 1000, @StartDate, @StartDate
		--FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
		FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
			INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
			INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
			INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID
		WHERE cs.ClientTypeID = 3 AND s.SessionDate BETWEEN @StartDate AND @EndDate
			AND sm.GrantorServiceID BETWEEN 401 AND 402
			AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND ai.DeletedDate IS NULL
		ORDER BY ClientTypeID;

	-- Item 16 Educational Presentations
		SELECT PresentationID, YouthTargeted, PresentationHours, ISNULL(PrepHours, 0) AS PrepHours, NumberAttended, IsPresentation
		FROM Presentations
		WHERE PresentationDate BETWEEN @StartDate AND @EndDate
			AND DeletedDate IS NULL
		ORDER BY YouthTargeted;

	-- Item17 Core Outcomes
		SELECT q.QuestionnaireID, qr.Response, qq.IsResource, qq.IsSafety,
			qq.IsShelter, qq.IsServices, qq.IsCounseling, qq.IsGroup,
			ShelterSurveys = 0, SupportSurveys = 0, CounselingSurveys = 0,
			GroupSurveys = 0
		FROM Grants g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
			INNER JOIN Surveys s ON s.SurveyID = gs.SurveyID
			INNER JOIN Questionnaires q ON s.SurveyID = q.SurveyID
			INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
			INNER JOIN Questions qq ON qr.QuestionID = qq.QuestionID
		WHERE g.GrantorID = 4
			AND ((@StartDate BETWEEN g.GrantStart AND g.GrantEnd) 
				OR (@EndDate BETWEEN g.GrantStart AND g.GrantEnd))
			AND q.CompletedDate BETWEEN @StartDate ANd @EndDate
			AND g.DeletedDate IS NULL AND q.DeletedDate IS NULL AND s.DeletedDate IS NULL; 

	-- Item 24 Staff trainings
		SELECT s.LastName + ', ' + s.FirstName AS StaffName, s.Title,
			ts.SessionDate, c.Credential AS Topic, ts.SessionHours AS Length
		FROM Staff s INNER JOIN StaffTraining st ON s.StaffID = st.StaffID
			INNER JOIN TrainingSessions ts ON st.SessionID = ts.SessionID
			INNER JOIN Credentials c ON ts.SubjectID = c.CredentialID
		WHERE ts.SessionDate BETWEEN @StartDate AND @EndDate 
			AND ts.DeletedDate IS NULL AND s.DeletedDate IS NULL
		ORDER BY StaffName, SessionDate; 

	-- Narrative Items
		SELECT
		Item3 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '3'), ''),
		Item4 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '4'), ''),
		--Item16B = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '16B'), ''),
		Item18 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '18'), ''),
		Item19 = ISNULL((SELECT TOP 1 Narrative FROM Re
portNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '19'), ''),
		Item20 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '20'), ''),
		Item21 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '21'), ''),
		Item22 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '22'), ''),
		Item23 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '23'), ''),
		Attachment = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = 'Attachment'), '');

rpt_RSHNspreadsheet
CREATE PROCEDURE dbo.rpt_RSHNspreadsheet
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- DV Program Budget And Community Awareness activities
    SELECT Budget = ISNULL(
        (SELECT Narrative
        FROM ReportNarratives
        WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '3'), '');

    -- Volunteer count and hours
        SELECT (ISNULL((SELECT COUNT(s.StaffID)
        FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
        WHERE (se.HireDate IS NULL OR se.HireDate <= @EndDate)
            AND (s.DateLeft IS NULL OR s.DateLeft > @EndDate)
            AND s.DeletedDate IS NULL AND s.Status = 2), 0)
        +
        ISNULL((SELECT SUM(OneTimeVolunteers)
        FROM VolunteerActivities
        WHERE DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate), 0)
        -
        ISNULL((SELECT COUNT(s.StaffID) AS NumberStaff
        FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
            LEFT OUTER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
            LEFT OUTER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
        WHERE s.Status = 2 And s.DeletedDate IS NULL AND
            (se.HireDate IS NULL Or se.HireDate <= @EndDate) AND
            (s.DateLeft IS NULL Or s.DateLeft > @EndDate ) AND
            (ss.StaffID IS NULL AND va.StaffID IS NULL)), 0)

        ),
        Hours =
        (
            (SELECT ISNULL(SUM(va.Hours), 0)
            FROM VolunteerActivity va INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
            WHERE vs.DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate)
            +
            (SELECT ISNULL(SUM(SessionHours), 0)
            FROM Sessions s INNER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
                INNER JOIN Staff ON ss.StaffID = Staff.StaffID
            WHERE Staff.Status = 2 AND s.DeletedDate IS NULL AND Staff.DeletedDate IS NULL
                AND SessionDate BETWEEN @StartDate AND @EndDate)
            +
            (SELECT ISNULL(SUM(OneTimeHours * OneTimeVolunteers), 0)
            FROM VolunteerActivities
            WHERE DeletedDate IS NULL AND ActivityDate BETWEEN @StartDate AND @EndDate)
        );

    -- New Clients
    -- Resident and Non-resident information; duplicates removed after table is retrieved
        SELECT p.ParticipantID AS ClientID, ClientTypeID = 1, p.Sex, p.DOB, i.EntryDate, Age = 0, p.EthnicityID, i.IntakeTypeID
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
        WHERE i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 2, 4)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL
        UNION ALL
        SELECT c.ChildID AS ClientID, ClientTypeID = 2, c.Sex, c.DOB, ci.EntryDate, Age = 0, c.EthnicityID, i.IntakeTypeID
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 2, 4)
            AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        ORDER BY ClientTypeID, ClientID, IntakeTypeID, EntryDate;

    -- Bednights
        SELECT Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DateDiff(day, i.EntryDate, i.ExitDate) END
        FROM Intakes i WHERE IntakeTypeID = 1 AND i.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.DeletedDate IS NULL
        UNION ALL
        SELECT Bednights = CASE
            WHEN EntryDate = ExitDate THEN 1
            WHEN ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN ExitDate > @EndDate THEN DATEDIFF(day, @StartDate , @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, ExitDate) END
        FROM Intakes
        WHERE IntakeTypeID = 1 AND EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate >= @StartDate )
            AND DeletedDate IS NULL
        UNION ALL
        SELECT Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, ci.EntryDate, ci.ExitDate) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE i.IntakeTypeID = 1 AND ci.EntryDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        UNION ALL
        SELECT Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, + @StartDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        WHERE i.IntakeTypeID = 1 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL Or ci.ExitDate >= @StartDate )
            AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
        UNION ALL
        SELECT Absences = CASE
            WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
            WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
            ELSE DATEDIFF(day, DateReturn, DateOut) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
        WHERE IntakeTypeID = 1 AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate )
            AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND ca.DateOut BETWEEN @StartDate AND @EndDate
        UNION ALL
        SELECT Absences = CASE
            WHEN DateReturn IS NULL THEN DATEDIFF(day, @EndDate, DateOut) - 1
            WHEN DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, DateOut) - 1
            ELSE DATEDIFF(day, DateReturn, DateOut) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN ChildAbsences ca ON ci.ChildIntakeID = ca.ChildIntakeID
        WHERE IntakeTypeID = 1 AND ci.EntryDate BETWEEN @StartDate AND @EndDate AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND ca.DateOut BETWEEN @StartDate AND @EndDate;

    -- Unmet Shelter Requests due to No Room
        SELECT COUNT(c.CallID) AS NoRoom
        FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        WHERE c.CallDate BETWEEN @StartDate AND @EndDate
            AND c.DeletedDate IS NULL
            AND c.CallSubjectID = 5 AND sr.ReasonDeniedID = 1;

    -- Hotline calls
        SELECT COUNT(CallID) AS HotlineCalls
        FROM Calls
        WHERE CallDate BETWEEN @StartDate AND @EndDate
            AND DeletedDate IS NULL AND CallTypeID < 4 AND WalkIn = 0;

    -- Services
        -- From Participants, including Youth/IPV primary clients
        SELECT cs.ClientTypeID, cs.ClientID, s.SessionHours, sm.GrantorServiceID,
            Age = 0, p.DOB, i.EntryDate
        --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID

        WHERE cs.ClientTypeID = 1 AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 401 AND 404
            AND i.IntakeTypeID IN (1, 2, 4) ---- Crisis, Non-Resident DV 
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
        UNION ALL
        -- From Children; add 1000000 to ClientID to keep it unique from ParticipantIDs
        SELECT cs.ClientTypeID, cs.ClientID + 1000000 AS ClientID, s.SessionHours, sm.GrantorServiceID,
            Age = 0, c.DOB, ci.EntryDate
        --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
        WHERE cs.ClientTypeID = 2 AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 401 AND 404
            AND i.IntakeTypeID IN (1, 2, 4) ---- Crisis, Non-Resident DV 
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
        UNION ALL
        -- Abusers
        SELECT cs.ClientTypeID, cs.ClientID, s.SessionHours, sm.GrantorServiceID,
            Age = 1000, @StartDate, @StartDate
        --FROM ServiceMap sm INNER JOIN Sessions s ON sm.ServiceID = s.ServiceID
        FROM ServiceMap sm INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN Sessions s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID
        WHERE cs.ClientTypeID = 3 AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 401 AND 402
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND ai.DeletedDate IS NULL
        ORDER BY ClientTypeID, ClientID;

    -- Presentations
        SELECT PresentationID, YouthTargeted, PresentationHours, ISNULL(PrepHours, 0) AS PrepHours, NumberAttended
        FROM Presentations
        WHERE PresentationDate BETWEEN @StartDate AND @EndDate AND IsPresentation = 1
            AND DeletedDate IS NULL
        ORDER BY YouthTargeted;

    -- Community Awareness activities (from Narratives)
        SELECT COUNT(PresentationID) AS Activities
        FROM Presentations
        WHERE PresentationDate BETWEEN @StartDate AND @EndDate
            AND IsPresentation = 0
            AND DeletedDate IS NULL;


rpt_ServiceAndFocus
CREATE PROCEDURE dbo.rpt_ServiceAndFocus
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT s.SessionID, s.ServiceID, s.FocusID, f.Focus, ss.ServiceName, s.ProgramID,
        cs.ClientTypeID, p.LastName + ', ' + p.FirstName + ' (P)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Focus f ON s.FocusID = f.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1 AND cs.DeletedDate IS NULL
        INNER JOIN Participants p ON cs.ClientID = p.ParticipantID
        LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Children
    SELECT s.SessionID, s.ServiceID, s.FocusID, f.Focus, ss.ServiceName, s.ProgramID,
        cs.ClientTypeID, c.LastName + ', ' + c.FirstName + ' (C)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Focus f ON s.FocusID = f.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2 AND cs.DeletedDate IS NULL
        INNER JOIN Children c ON cs.ClientID = c.ChildID
    	 LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND c.DeletedDate IS NULL
    UNION ALL
    -- Abusers
    SELECT s.SessionID, s.ServiceID, s.FocusID, f.Focus, ss.ServiceName, s.ProgramID, 
        cs.ClientTypeID, a.LastName + ', ' + a.FirstName + ' (A)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Focus f ON s.FocusID = f.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 3 AND cs.DeletedDate IS NULL
        INNER JOIN Abusers a ON cs.ClientID = a.AbuserID
    	 LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND a.DeletedDate IS NULL
    UNION ALL
    -- Community Members
    SELECT s.SessionID, s.ServiceID, s.FocusID, f.Focus, ss.ServiceName, s.ProgramID,
        cs.ClientTypeID, cm.LastName + ', ' + cm.FirstName + ' (M)' AS Client, s.SessionDate, s.SessionHours,
         ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Focus f ON s.FocusID = f.FocusID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 4 AND cs.DeletedDate IS NULL
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID
        LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
        LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND cm.DeletedDate IS NULL
    UNION ALL
    -- Caller Services
    SELECT cs.SessionID, cs.ServiceID, cs.FocusID, f.Focus, s.ServiceName, cs.ProgramID,
        ClientTypeID = 0, c.LastName + ', ' + c.FirstName + ' (H)' AS Client, c.CallDate, cs.SessionHours,
        ISNULL(st.LastName + ' , ' + st.FirstName, '') AS Staff
    FROM CallServices cs INNER JOIN Calls c ON cs.CallID = c.CallID
        INNER JOIN Focus f ON cs.FocusID = f.FocusID
        INNER JOIN Services s ON cs.ServiceID = s.ServiceID
        LEFT OUTER JOIN StaffCallService scs ON cs.SessionID = scs.SessionID
        LEFT OUTER JOIN Staff st ON scs.StaffID = st.StaffID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
    ORDER BY ss.ServiceName, f.Focus, SessionDate, s.SessionID, ClientTypeID, Client;

rpt_ServiceFocusSummary
CREATE PROCEDURE rpt_ServiceFocusSummary
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Participants
	SELECT s.SessionID, s.ServiceID, s.FocusID, sf.ServiceFocusID, s.ProgramID, 
		ss.ServiceName, f.Focus, s.SessionHours, s.LocationID,
		NumberInSession = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID),
		s.NumberStaff, cs.ClientTypeID,
		cs.ClientID AS ParticipantID, ChildID = NULL, AbuserID = NULL, MemberID = NULL, CallerID = NULL
	FROM Sessions s INNER JOIN Services ss ON ss.ServiceID = s.ServiceID
		INNER JOIN Focus f ON s.FocusID = f.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Participants p on cs.ClientID = p.ParticipantID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
	WHERE cs.ClientTypeID = 1 AND cs.DeletedDate IS NULL
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL AND p.DeletedDate IS NULL
	UNION ALL
	-- Children
	SELECT s.SessionID, s.ServiceID, s.FocusID, sf.ServiceFocusID, s.ProgramID, 
		ss.ServiceName, f.Focus, s.SessionHours, s.LocationID,
		NumberInSession = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID),
		s.NumberStaff, cs.ClientTypeID,
		ParticipantID = NULL, cs.ClientID AS ChildID, AbuserID = NULL, MemberID = NULL, CallerID = NULL
	FROM Sessions s INNER JOIN Services ss ON ss.ServiceID = s.ServiceID
		INNER JOIN Focus f ON s.FocusID = f.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Children c ON cs.ClientID = c.ChildID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
	WHERE cs.ClientTypeID = 2 AND cs.DeletedDate IS NULL
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL 
		--AND c.DeletedDate IS NULL
	UNION ALL
	-- Abusers
	SELECT s.SessionID, s.ServiceID, s.FocusID, sf.ServiceFocusID, s.ProgramID, 
		ss.ServiceName, f.Focus, s.SessionHours, s.LocationID,
		NumberInSession = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID),
		s.NumberStaff, cs.ClientTypeID,
		ParticipantID = NULL, ChildID = NULL, cs.ClientID AS AbuserID, MemberID = NULL,  CallerID = NULL
	FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
		INNER JOIN Focus f ON s.FocusID = f.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN Abusers a ON cs.ClientID = a.AbuserID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceFocusID AND s.FocusID = sf.FocusID
	WHERE cs.ClientTypeID = 3 AND cs.DeletedDate IS NULL
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL AND a.DeletedDate IS NULL
	UNION ALL
	-- Community Members
	SELECT s.SessionID, s.ServiceID, s.FocusID, sf.ServiceFocusID, s.ProgramID, 
		ss.ServiceName, f.Focus, s.SessionHours, s.LocationID,
		NumberInSession = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID),
		s.NumberStaff, cs.ClientTypeID,
		ParticipantID = NULL, ChildID = NULL, AbuserID = NULL, cs.ClientID AS MemberID, CallerID = NULL
	FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
		INNER JOIN Focus f ON s.FocusID = f.FocusID
		INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
		INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID
		INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceFocusID AND s.FocusID = sf.FocusID
	WHERE cs.ClientTypeID = 4 AND cs.DeletedDate IS NULL
		AND s.SessionDate BETWEEN @StartDate AND @EndDate
		AND s.DeletedDate IS NULL AND cm.DeletedDate IS NULL
	UNION ALL
	-- Callers
	SELECT cs.SessionID + 2000000 AS SessionID, cs.ServiceID, cs.FocusID, sf.ServiceFocusID, cs.ProgramID,
		s.ServiceName, f.Focus, cs.SessionHours, LocationID = 1,
		NumberInSession = 1, cs.NumberStaff, ClientTypeID = 5,
		ParticipantID = NULL, ChildID = NULL, AbuserID = NULL, MemberID = NULL, c.CallID AS CallerID
	FROM CallServices cs INNER JOIN Calls c ON cs.CallID = c.CallID
		INNER JOIN Services s ON cs.ServiceID = s.ServiceID
		INNER JOIN Focus f ON cs.FocusID = f.FocusID
		INNER JOIN ServiceFocus sf ON cs.ServiceID = sf.ServiceID AND cs.FocusID = sf.FocusID
	WHERE c.CallDate BETWEEN @StartDate AND @EndDate
		AND c.DeletedDate IS NULL
	ORDER BY ServiceName, Focus, SessionID, ClientTypeID

rpt_ServiceLocations
CREATE PROCEDURE dbo.rpt_ServiceLocations
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT s.ServiceID, s.SessionID, s.LocationID, s.SessionHours, ss.ServiceName, s.NumberStaff,
        Location = CASE WHEN s.LocationID = 1 THEN 'Unknown' ELSE x.Location END, 
        cs.ClientTypeID * 1000000 + cs.ClientID AS ClientID, cs.ClientTypeID,
        NumberClients = (SELECT COUNT(ClientID) FROM ClientSessions cs WHERE cs.SessionID = s.SessionID AND cs.DeletedDate IS NULL)
    FROM Services ss INNER JOIN Sessions s ON s.ServiceID = ss.ServiceID
        INNER JOIN xServiceLocation x ON s.LocationID = x.LocationID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL
    ORDER BY Location, ServiceName, SessionID;

rpt_ServicesByClient
CREATE PROCEDURE dbo.rpt_ServicesByClient
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	-- Participants
    SELECT p.OptionalIdentifier, ClientID, LastName + ', ' + FirstName + ' ' + MI AS ClientName, ServiceName, SessionDate, SessionHours, NumberStaff, ClientType = 1,
    cs.ClientTypeID
    FROM Participants p INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID And ClientTypeID = 1
    INNER JOIN Sessions s ON cs.SessionID = s.SessionID
    INNER JOIN Services ON Services.ServiceID = s.ServiceID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
    AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Children
    SELECT OptionalIdentifier = '', ClientID, LastName + ', ' + FirstName + ' ' + MI AS ClientName, ServiceName, SessionDate, SessionHours, NumberStaff, ClientType = 2,
    cs.ClientTypeID
    FROM Children c INNER JOIN ClientSessions cs ON c.ChildID = cs.ClientID And ClientTypeID = 2
    INNER JOIN Sessions s ON cs.SessionID = s.SessionID
    INNER JOIN Services ON Services.ServiceID = s.ServiceID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
    AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND c.DeletedDate IS NULL
    UNION ALL
    -- Abusers
    SELECT OptionalIdentifier = '', ClientID, LastName + ', ' + FirstName + ' ' + MI AS ClientName, ServiceName, SessionDate, SessionHours, NumberStaff, ClientType = 3,
    cs.ClientTypeID
    FROM Abusers a INNER JOIN ClientSessions cs ON a.AbuserID = cs.ClientID And ClientTypeID = 3
    INNER JOIN Sessions s ON cs.SessionID = s.SessionID
    INNER JOIN Services ON Services.ServiceID = s.ServiceID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
    AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND a.DeletedDate IS NULL
    -- Callers
    SELECT OptionnalIdentifier = '', c.CallID AS ClientID, c.LastName + ', ' + FirstName + ' ' + MI AS ClientName, ServiceName, 
        CallDate as SessionDate, SessionHours, NumberStaff, ClientType = 0, ClientTypeID = 0
    FROM Calls c INNER JOIN CallServices cs ON c.CallID = cs.CallID
        INNER JOIN [Services] s ON cs.ServiceID = s.ServiceID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
    -- Community Members
    SELECT cm.OptionalIdentifier, ClientID, LastName + ', ' + FirstName + ' ' + MI AS ClientName, ServiceName, SessionDate, SessionHours, NumberStaff, ClientType = 4,
    cs.ClientTypeID
    FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID And ClientTypeID = 4
    INNER JOIN Sessions s ON cs.SessionID = s.SessionID
    INNER JOIN Services ON Services.ServiceID = s.ServiceID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
    AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND cm.DeletedDate IS NULL 
    ORDER BY ClientType, ClientName, ServiceName, SessionDate;

rpt_ServicesByProgram
CREATE PROCEDURE dbo.rpt_ServicesByProgram
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Participants
    SELECT Program, ServiceName, s.SessionID, NumberStaff, SessionHours AS ClientHours, SessionHours,
		pp.ParticipantID, ChildID = NULL, AbuserID = NULL, MemberID = NULL, CallerID = NULL, cs.ClientTypeID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)
    FROM Programs p INNER JOIN [Sessions] s ON p.ProgramID = s.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Participants pp ON pp.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND cs.DeletedDate IS NULL AND pp.DeletedDate IS NULL
    UNION ALL
    -- Children
    SELECT Program, ServiceName, s.SessionID, NumberStaff, SessionHours AS ClientHours, SessionHours,
		ParticipantID = NULL, c.ChildID, AbuserID = NULL, MemberID = NULL, CallerID = NULL, cs.ClientTypeID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)
    FROM Programs p INNER JOIN [Sessions] s ON p.ProgramID = s.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Children c ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND cs.DeletedDate IS NULL AND c.DeletedDate IS NULL
    UNION ALL
    -- Abusers
    SELECT Program, ServiceName, s.SessionID, NumberStaff, SessionHours AS ClientHours, SessionHours,
		ParticipantID = NULL, ChildID = NULL, a.AbuserID, MemberID = NULL, CallerID = NULL, cs.ClientTypeID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)
    FROM Programs p INNER JOIN [Sessions] s ON p.ProgramID = s.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN Abusers a ON a.AbuserID = cs.ClientID AND cs.ClientTypeID = 3
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND cs.DeletedDate IS NULL AND a.DeletedDate IS NULL
    UNION ALL
    -- Call services rendered via hotline
    SELECT Program, ServiceName, cs.SessionID, NumberStaff, SessionHours AS ClientHours, SessionHours,
        ParticipantID = NULL, ChildID = NULL, AbuserID = NULL, MemberID = NULL, c.CallID AS CallerID, ClientTypeID = 0,
		NumberInGroup = 1
    FROM Programs p INNER JOIN CallServices cs ON p.ProgramID = cs.ProgramID
        INNER JOIN Calls c ON cs.CallID = c.CallID
        INNER JOIN [Services] s ON cs.ServiceID = s.ServiceID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
    UNION ALL
    -- Community Members
    SELECT Program, ServiceName, s.SessionID, NumberStaff, SessionHours AS ClientHours, SessionHours,
        ParticipantID = NULL, ChildID = NULL, AbuserID = NULL, cm.MemberID AS MemberID, CallerID = NULL, cs.ClientTypeID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = s.SessionID AND DeletedDate IS NULL)
    FROM Programs p INNER JOIN [Sessions] s ON p.ProgramID = s.ProgramID
        INNER JOIN [Services] ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        INNER JOIN CommunityMembers cm ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND cs.DeletedDate IS NULL AND p.DeletedDate IS NULL
    ORDER BY Program, ServiceName, s.SessionID;

rpt_ServicesByStaff
CREATE PROCEDURE rpt_ServicesByStaff	
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
	-- Participants
    SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, SessionHours, ServiceName, s.StaffID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = sss.SessionID AND DeletedDate IS NULL),
		i.IntakeTypeID, x.IntakeType
    FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
        INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        INNER JOIN Services sv ON sss.ServiceID = sv.ServiceID
		INNER JOIN ClientSessions cs ON sss.SessionID = cs.SessionID
		INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
		AND cs.ClientTypeID = 1
        AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL
	-- Children
	UNION ALL
	SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, SessionHours, ServiceName, s.StaffID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = sss.SessionID AND DeletedDate IS NULL),
		i.IntakeTypeID, x.IntakeType
    FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
        INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        INNER JOIN Services sv ON sss.ServiceID = sv.ServiceID
		INNER JOIN ClientSessions cs ON sss.SessionID = cs.SessionID
		INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
		INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
		INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
		AND cs.ClientTypeID = 2
        AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL
	-- Community Members
	UNION ALL
	SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, SessionHours, ServiceName, s.StaffID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = sss.SessionID AND DeletedDate IS NULL),
		IntakeTypeID = 4, IntakeType = 'Non-Resident DV'
    FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
        INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        INNER JOIN Services sv ON sss.ServiceID = sv.ServiceID
		INNER JOIN ClientSessions cs ON sss.SessionID = cs.SessionID
	WHERE SessionDate BETWEEN @StartDate AND @EndDate
		AND cs.ClientTypeID = 4
        AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL
	-- Abusers
	UNION ALL
	SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, SessionHours, ServiceName, s.StaffID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = sss.SessionID AND DeletedDate IS NULL),
		IntakeTypeID = 7, IntakeType = 'Abuser Counseling'
    FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
        INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        INNER JOIN Services sv ON sss.ServiceID = sv.ServiceID
		INNER JOIN ClientSessions cs ON sss.SessionID = cs.SessionID
		INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
		AND cs.ClientTypeID = 3
        AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL
	UNION ALL 
	-- Any Participant/Child/Abuser client type where the service was listed
	-- as 'NOT during an intake period', (IntakeID = 0 and ClientTypeID <> 4
	SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, SessionHours, ServiceName, s.StaffID,
		NumberInGroup = 
			(SELECT COUNT(SessionID) FROM ClientSessions WHERE SessionID = sss.SessionID AND DeletedDate IS NULL),
		IntakeTypeID = 8, IntakeType = 'Unknown'
    FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID
        INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID
        INNER JOIN Services sv ON sss.ServiceID = sv.ServiceID
		INNER JOIN ClientSessions cs ON sss.SessionID = cs.SessionID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
		AND cs.ClientTypeID <> 4 AND IntakeID = 0
        AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL
    UNION ALL
    SELECT s.LastName + ', ' + s.FirstName + ' ' + s.MI AS FullName, cs.SessionHours, ss.ServiceName, s.StaffID,
		NumberInGroup = 1, IntakeTypeID = 9, IntakeType = 'Hotline'
    FROM Staff s INNER JOIN StaffCallService scs ON s.StaffID = scs.StaffID
        INNER JOIN CallServices cs ON scs.SessionID = cs.SessionID
        INNER JOIN Services ss ON cs.ServiceID = ss.ServiceID
        INNER JOIN Calls c ON cs.CallID = c.CallID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL
	ORDER BY IntakeTypeID, FullName, ServiceName;
	-- Get the outreach hours as well
	SELECT s.StaffID, s.LastName + ', ' + s.FirstName AS StaffName, p.Location, 
		ISNULL(p.PresentationHours, 0) AS PresentationHours, p.PresentationDate
	FROM Presentations p INNER JOIN StaffPresentations sp ON p.PresentationID = sp.PresentationID
		INNER JOIN Staff s ON sp.StaffID = s.StaffID
	WHERE p.PresentationDate BETWEEN @StartDate AND @EndDate AND p.DeletedDate IS NULL
		AND s.DeletedDate IS NULL
	ORDER BY StaffName;

rpt_ServicesByType
CREATE PROCEDURE dbo.rpt_ServicesByType
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Participants
    SELECT s.SessionID, s.ServiceID, s.ProgramID, pp.Program, ss.ServiceName,
        cs.ClientTypeID, p.LastName + ', ' + p.FirstName + ' (P)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Programs pp ON s.ProgramID = pp.ProgramID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1 AND cs.DeletedDate IS NULL
        INNER JOIN Participants p ON cs.ClientID = p.ParticipantID
        LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND p.DeletedDate IS NULL
    UNION ALL
    -- Children
    SELECT s.SessionID, s.ServiceID, s.ProgramID, pp.Program, ss.ServiceName,
        cs.ClientTypeID, c.LastName + ', ' + c.FirstName + ' (C)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Programs pp ON s.ProgramID = pp.ProgramID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2 AND cs.DeletedDate IS NULL
        INNER JOIN Children c ON cs.ClientID = c.ChildID
    	 LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND c.DeletedDate IS NULL
    UNION ALL
    -- Abusers
    SELECT s.SessionID, s.ServiceID, s.ProgramID, pp.Program, ss.ServiceName, 
        cs.ClientTypeID, a.LastName + ', ' + a.FirstName + ' (A)' AS Client, s.SessionDate, s.SessionHours,
    	 ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Programs pp ON s.ProgramID = pp.ProgramID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 3 AND cs.DeletedDate IS NULL
        INNER JOIN Abusers a ON cs.ClientID = a.AbuserID
    	 LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
     	 LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND a.DeletedDate IS NULL
    UNION ALL
    -- Community Members
    SELECT s.SessionID, s.ServiceID, s.ProgramID, pp.Program, ss.ServiceName,
        cs.ClientTypeID, cm.LastName + ', ' + cm.FirstName + ' (M)' AS Client, s.SessionDate, s.SessionHours,
         ISNULL(st.LastName + ', ' + st.FirstName, '') AS Staff
    FROM Services ss INNER JOIN Sessions s ON ss.ServiceID = s.ServiceID
        INNER JOIN Programs pp ON s.ProgramID = pp.ProgramID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 4 AND cs.DeletedDate IS NULL
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID
        LEFT OUTER JOIN StaffSessions sss ON s.SessionID = sss.SessionID
        LEFT OUTER JOIN Staff st ON sss.StaffID = st.StaffID AND st.DeletedDate IS NULL
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND cm.DeletedDate IS NULL
    UNION ALL
    -- Caller Services
    SELECT cs.SessionID, cs.ServiceID, cs.ProgramID, p.Program, s.ServiceName,
        ClientTypeID = 0, c.LastName + ', ' + c.FirstName + ' (H)' AS Client, c.CallDate, cs.SessionHours,
        ISNULL(st.LastName + ' , ' + st.FirstName, '') AS Staff
    FROM CallServices cs INNER JOIN Calls c ON cs.CallID = c.CallID
        INNER JOIN Programs p ON cs.ProgramID = p.ProgramID
        INNER JOIN Services s ON cs.ServiceID = s.ServiceID
        LEFT OUTER JOIN StaffCallService scs ON cs.SessionID = scs.SessionID
        LEFT OUTER JOIN Staff st ON scs.StaffID = st.StaffID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
    ORDER BY ss.ServiceName, pp.Program, SessionDate, s.SessionID, ClientTypeID, Client;

rpt_ServicesSummary
CREATE PROCEDURE rpt_ServicesSummary
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Participants
    SELECT Program, ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (P)' AS FullName, OptionalIdentifier,
        pp.ParticipantID AS ClientID, i.IntakeTypeID, i.EntryDate, i.ExitDate, ServiceName, SessionDate, SessionHours,
        ss.ServiceID, p.ProgramID, s.LocationID
    FROM Programs p INNER JOIN Sessions s ON s.ProgramID = p.ProgramID
        INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 1
        INNER JOIN Intakes i ON cs.IntakeID = i.IntakeID
        INNER JOIN Participants pp ON i.ParticipantID = pp.ParticipantID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND pp.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND i.DeletedDate IS NULL
    UNION ALL
    -- Children
    SELECT Program, ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (C)' AS FullName, OptionalIdentifier = '',
        c.ChildID AS ClientID, i.IntakeTypeID, ci.EntryDate, ci.ExitDate, ServiceName, SessionDate, SessionHours,
        ss.ServiceID, p.ProgramID, s.LocationID
    FROM Programs p INNER JOIN Sessions s ON s.ProgramID = p.ProgramID
        INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 2
        INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND i.DeletedDate IS NULL AND ci.DeletedDate IS NULL
    UNION ALL
    -- Community Members
    SELECT Program, ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (M)' AS FullName, '',
        cm.MemberID AS ClientID, 0, NULL, NULL, ServiceName, SessionDate, SessionHours,
        ss.ServiceID, p.ProgramID, s.LocationID
    FROM Programs p INNER JOIN Sessions s ON s.ProgramID = p.ProgramID
        INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 4
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND cs.DeletedDate IS NULL
    UNION ALL
    -- Abusers
    SELECT Program, ClientTypeID, LastName + ', ' + FirstName + ' ' + MI + ' (A)' AS FullName, OptionalIdentifier = '',
        a.AbuserID AS ClientID, IntakeTypeID = 7, ai.EntryDate, ai.ExitDate, ServiceName, SessionDate, SessionHours,
            ss.ServiceID, p.ProgramID, s.LocationID
    FROM Programs p INNER JOIN Sessions s ON s.ProgramID = p.ProgramID
        INNER JOIN Services ss ON s.ServiceID = ss.ServiceID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID AND cs.ClientTypeID = 3
        INNER JOIN AbuserIntakes ai ON cs.IntakeID = ai.AbuserIntakeID
        INNER JOIN Abusers a ON ai.AbuserID = a.AbuserID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND a.DeletedDate IS NULL AND ss.DeletedDate IS NULL AND s.DeletedDate IS NULL AND ai.DeletedDate IS NULL
    UNION ALL
    SELECT Program, ClientTypeID = 0, LastName + ', ' + FirstName + ' ' + MI + ' (H)' AS Fullname, '',
        c.CallID AS ClientID, -1, NULL, NULL, ServiceName, CallDate, SessionHours,
        s.ServiceID, p.ProgramID, LocationID = 0
    FROM Programs p INNER JOIN CallServices cs ON p.ProgramID = cs.ProgramID
        INNER JOIN Services s ON cs.ServiceID = s.ServiceID
        INNER JOIN Calls c ON cs.CallID = c.CallID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
    ORDER BY Program, IntakeTypeID, ClientTypeID, FullName, ServiceName, SessionDate;

rpt_StaffAdvocates
CREATE PROCEDURE dbo.rpt_StaffAdvocates
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT s.StaffID, s.LastName + ', ' + s.FirstName AS StaffName, StaffRole,
        p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS Participant,
        i.EntryDate, x.IntakeType, ISNULL(PhaseName, 'Not Assigned') AS Phase, BeginDate, ProjectedEnd,
        ci.ChildIntakeID
    FROM Staff s INNER JOIN IntakeStaff si ON s.StaffID = si.StaffID
        INNER JOIN Intakes i ON si.IntakeID = i.IntakeID
        INNER JOIN Participants p ON p.ParticipantID = i.ParticipantID
        INNER JOIN xIntakeType x ON x.IntakeTypeID = i.IntakeTypeID
        LEFT OUTER JOIN IntakePhase ip ON i.IntakeID = ip.IntakeID AND @StartDate BETWEEN BeginDate AND ISNULL(CompletedDate, '6/1/2079')
        LEFT OUTER JOIN Phases ph ON ph.PhaseID = ip.PhaseID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID AND ci.DeletedDate IS NULL
    WHERE @StartDate BETWEEN i.EntryDate AND ISNULL(i.ExitDate, '6/1/2079')
        AND s.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
    ORDER BY s.StaffID, p.ParticipantID;

rpt_StaffMemberTraining
CREATE PROCEDURE dbo.rpt_StaffMemberTraining
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT LastName + ', ' + FirstName + ' ' + MI AS StaffName, SessionDate, SessionHours, SessionNote, c.Credential AS Subject
    FROM Staff s INNER JOIN StaffTraining st on s.StaffID = st.StaffID
    INNER JOIN TrainingSessions ts ON st.SessionID = ts.SessionID
    INNER JOIN Credentials c ON ts.SubjectID = c.CredentialID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate ORDER BY StaffName, SessionDate, Subject;

rpt_StaffPresentations
CREATE PROCEDURE dbo.rpt_StaffPresentations
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT p.PresentationID, p.PresentationDate, p.PresentationHours, p.NumberAttended, pt.TopicID, Topic,
        ISNULL(sp.StaffID, 0) AS StafFID, ISNULL(LastName + ', ' + FirstName, '') AS FullName, Location, IsPresentation
    FROM xTopic x INNER JOIN PresentationTopics pt ON x.TopicID = pt.TopicID
        RIGHT OUTER JOIN Presentations p ON pt.PresentationID = p.PresentationID
        LEFT OUTER JOIN StaffPresentations sp ON p.PresentationID = sp.PresentationID
        LEFT OUTER JOIN Staff s ON s.StaffID = sp.StaffID
    WHERE PresentationDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL
    ORDER BY IsPresentation DESC, PresentationDate, PresentationID, TopicID;

rpt_StaffRequirements
CREATE PROCEDURE dbo.rpt_StaffRequirements
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT CredentialID AS RequirementID, [Credential] AS Requirement, CompletedDate, DueDate,
        LastName + ', ' + FirstName + ' ' + MI AS FullName
    FROM Credentials c INNER JOIN StaffRequirements sr ON c.CredentialID = sr.RequirementID
        INNER JOIN Staff s ON sr.StaffID = s.StaffID
    WHERE c.Frequency > -2 AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL
        AND s.DateLeft IS NULL
        AND (CompletedDate IS NULL OR DueDate <= @StartDate)
    ORDER BY Requirement, DueDate, FullName;

rpt_StaffRoster
CREATE PROCEDURE dbo.rpt_StaffRoster
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT s.StaffID, s.Status, LastName, FirstName, MI, '' AS FullName, Title, HireDate, DOB, WorkStatus = CASE
    WHEN [Status] = 0 THEN 'Full Time' WHEN [Status] = 1 THEN 'Part Time' WHEN [Status] = 2 THEN 'Volunteers' END
    FROM Staff s LEFT OUTER JOIN StaffExt se ON s.StaffID = se.StaffID
    WHERE s.DeletedDate IS NULL AND (DateLeft IS NULL OR DateLeft > @StartDate)
    AND ISNULL(HireDate, '1/1/1900') <= @StartDate
    ORDER BY s.Status, LastName, FirstName, MI;

rpt_StaffServicesToClients
CREATE PROCEDURE rpt_StaffServicesToClients
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS 
	-- Participants      
    SELECT st.LastName + ', ' + st.FirstName AS StaffName, cs.ClientTypeID,
        sv.ServiceName, sv.ServiceID, s.SessionHours, 
        s.SessionID, cs.ClientTypeID, ss.StaffID, 
        p.LastName + ', ' + p.FirstName + ' (P)' AS ClientName,
		ISNULL(i.LocationID, 0) AS LocationID 
    FROM Services sv INNER JOIN Sessions s ON sv.ServiceID = s.ServiceID
        INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
        INNER JOIN Staff st ON ss.StaffID = st.StaffID
        INNER JOIN ClientSessions cs ON ss.SessionID = cs.SessionID
        INNER JOIN Participants p ON cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
		LEFT OUTER JOIN Intakes i ON cs.IntakeID = i.IntakeID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND p.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND st.DeletedDate IS NULL
    UNION ALL
	-- Children
    SELECT st.LastName + ', ' + st.FirstName AS StaffName, cs.ClientTypeID,
        sv.ServiceName, sv.ServiceID, s.SessionHours,
        s.SessionID, cs.ClientTypeID, ss.StaffID, 
        c.LastName + ', ' + c.FirstName + ' (C)' AS ClientName,
		ISNULL(i.LocationID, 0) AS LocationID 
    FROM Services sv INNER JOIN Sessions s ON sv.ServiceID = s.ServiceID
        INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
        INNER JOIN Staff st ON ss.StaffID = st.StaffID
        INNER JOIN ClientSessions cs ON ss.SessionID = cs.SessionID
        INNER JOIN Children c ON cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
		LEFT OUTER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID
		LEFT OUTER JOIN Intakes i ON ci.IntakeID = i.IntakeID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND st.DeletedDate IS NULL
    UNION ALL
	-- Community Members
    SELECT st.LastName + ', ' + st.FirstName AS StaffName, cs.ClientTypeID,
        sv.ServiceName, sv.ServiceID, s.SessionHours,
        s.SessionID, 3, ss.StaffID, 
        cm.LastName + ', ' + cm.FirstName + ' (CM)' AS ClientName,
		LocationID = 0 
    FROM Services sv INNER JOIN Sessions s ON sv.ServiceID = s.ServiceID
        INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
        INNER JOIN Staff st ON ss.StaffID = st.StaffID
        INNER JOIN ClientSessions cs ON ss.SessionID = cs.SessionID
        INNER JOIN CommunityMembers cm ON cs.ClientID = cm.MemberID AND cs.ClientTypeID = 4
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND st.DeletedDate IS NULL
    UNION ALL
	-- Abusers
    SELECT st.LastName + ', ' + st.FirstName AS StaffName, cs.ClientTypeID,
        sv.ServiceName, sv.ServiceID, s.SessionHours,
        s.SessionID, 4, ss.StaffID, 
        a.LastName + ', ' + a.FirstName + ' (A)' AS ClientName,
		LocationID = 0 
    FROM Services sv INNER JOIN Sessions s ON sv.ServiceID = s.ServiceID
        INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
        INNER JOIN Staff st ON ss.StaffID = st.StaffID
        INNER JOIN ClientSessions cs ON ss.SessionID = cs.SessionID
        INNER JOIN Abusers a ON cs.ClientID = a.AbuserID AND cs.ClientTypeID = 3
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND a.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL AND st.DeletedDate IS NULL
    ORDER BY StaffName, cs.ClientTypeID, ClientName, sv.ServiceName;

rpt_STOP
CREATE PROCEDURE rpt_STOP
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Primary Victims:  All Intakes where VictimType is Domestic Violence (5), Sexual Assault (6), or Stalking (9)
	--  Resident victims
        SELECT p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS VictimName, p.EthnicityID,
            xe.Ethnicity, p.Sex, p.DOB, i.EntryDate, Age = DATEDIFF(year, p.DOB, i.EntryDate), i.AbuserRelationshipID,
            xi.IntakeType, xa.AbuserRelationship, xc.CallSubject AS VictimType, ivt.VictimTypeID, Disability = CAST(CASE
                WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1 OR i.ChronicHealthCondition = 1
                THEN 1 ELSE 0 END AS BIT),
            Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL),
            LinkedCall = CAST(CASE WHEN ic.CallID IS NULL THEN 0 ELSE 1 END AS BIT)
        FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN xAbuserRelationship xa ON i.AbuserRelationshipID = xa.AbuserRelationshipID
            INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
            INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
            LEFT OUTER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            LEFT OUTER JOIN xCallSubject xc ON ivt.VictimTypeID = xc.CallSubjectID
        WHERE ivt.VictimTypeID IN (5, 6, 9)
            AND i.IntakeTypeID IN (1, 2, 3, 5)
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
		UNION ALL
	--  Non-Resident victims who received a service
        SELECT p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS VictimName, p.EthnicityID,
            xe.Ethnicity, p.Sex, p.DOB, i.EntryDate, Age = DATEDIFF(year, p.DOB, i.EntryDate), i.AbuserRelationshipID,
            xi.IntakeType, xa.AbuserRelationship, xc.CallSubject AS VictimType, ivt.VictimTypeID, Disability = CAST(CASE
                WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1 OR i.ChronicHealthCondition = 1
                THEN 1 ELSE 0 END AS BIT),
            Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL),
            LinkedCall = CAST(CASE WHEN ic.CallID IS NULL THEN 0 ELSE 1 END AS BIT)
        FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN xAbuserRelationship xa ON i.AbuserRelationshipID = xa.AbuserRelationshipID
            INNER JOIN xEthnicity xe ON p.EthnicityID = xe.EthnicityID
            INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
            LEFT OUTER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            LEFT OUTER JOIN xCallSubject xc ON ivt.VictimTypeID = xc.CallSubjectID
        WHERE ivt.VictimTypeID IN (5, 6, 9)
            AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
			AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
			AND (SELECT TOP 1 cs.SessionID 
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID 
				WHERE ClientID = p.ParticipantID AND ClientTypeID = 1
					AND s.SessionDate BETWEEN @StartDate AND @EndDate) IS NOT NULL
        ORDER BY p.ParticipantID, VictimName, Children DESC;

    -- Callers/Walk-ins requesting shelter that were denied
        SELECT x.ReasonDenied, c.CallDate, c.LastName + ', ' + c.FirstName AS Caller, c.CallSubjectID
        FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
            INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
        WHERE c.CallDate BETWEEN @StartDate AND @EndDate
            AND sr.ReasonDeniedID > 0
            AND c.CallSubjectID IN (5, 6, 9)
        ORDER BY ReasonDenied;

    -- Hotline Calls; all crisis and info/referral calls
        SELECT COUNT(c.CallID) AS TotalCalls
        FROM Calls c
        WHERE c.CallDate BETWEEN @StartDate AND @EndDate
            AND c.DeletedDate IS NULL
            AND c.CallTypeID < 4; 

    -- Services to primary victims where service is mapped to STOP service types
        SELECT p.ParticipantID, s.SessionID, ivt.VictimTypeID, ss.ServiceName,
            p.LastName + ', ' + p.FirstName AS VictimName,
            sm.GrantorServiceID, gs.GrantorService, s.SessionDate
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN ClientSessions cs ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN Services ss ON sf.ServiceID = ss.ServiceID
            INNER JOIN GrantorServices gs ON sm.GrantorServiceID = gs.GrantorServiceID AND gs.GrantorID = 8
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND sm.GrantorServiceID BETWEEN 801 AND 811
            AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        ORDER BY VictimName, ParticipantID, sm.GrantorServiceID, SessionDate; 

   -- Bednights for primary victims and children
        -- Dummy Line; always subtract 1 from total (distinct) ParticipantID and ChildID
        SELECT ParticipantID = 0, ChildID = 0, ClientName = 'Dummy Client',
            ClientType = 0, EntryDate = @StartDate, IntakeType = 'Dummy', IntakeTypeID = 0,
            IntakeID = 0, Bednights = 0
        UNION ALL
        -- New Participants
        SELECT p.ParticipantID, ChildID = 0, p.LastName + ', ' + p.FirstName  AS ClientName,
            ClientType = 1, EntryDate, x.IntakeType, i.IntakeTypeID,
            i.IntakeID, Bednights = CASE
                WHEN i.EntryDate = i.ExitDate THEN 1
                WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
                WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
                ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END
        FROM Intakes i INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE EntryDate BETWEEN @StartDate AND @EndDate
            AND i.DeletedDate IS NULL
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        UNION ALL
        -- Carryover Participants
        SELECT p.ParticipantID, ChildID = 0, p.LastName + ', ' + p.FirstName  AS ClientName,
            ClientType = 1, EntryDate, x.IntakeType, i.IntakeTypeID,
            i.IntakeID, Bednights = CASE
                WHEN i.EntryDate = i.ExitDate THEN 1
                WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                ELSE DATEDIFF(day, @StartDate, i.ExitDate) END
        FROM Intakes i INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.Delete
dDate IS NULL
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        UNION ALL
        -- New Children
        SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
            ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
            ci.ChildIntakeID, Bednights = CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        UNION ALL
        -- Carryover Children
        SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
            ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
            ci.ChildIntakeID, Bednights = CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END
        FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        UNION ALL
        -- Child Absences for New Children
        SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
            ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
            ci.ChildIntakeID, Bednights = CASE
                WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
                WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
                WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
                ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END
        FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND ci.EntryDate BETWEEN @StartDate AND @EndDate
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ca.DateOut BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
        UNION ALL
        -- Child Absences for Carryover Children
        SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
            ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
            ci.ChildIntakeID, Bednights = CASE
                WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
                WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
                WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
                ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) END
        FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.IntakeTypeID IN (1, 2, 3, 5)
            AND ivt.VictimTypeID IN (5, 6, 9, 12)
            AND ca.DateOut <= @EndDate
            AND (ca.DateReturn IS NULL OR ca.DateReturn > @StartDate)
        ORDER BY ClientType, ClientName, IntakeID;

rpt_STOPsa
CREATE PROCEDURE dbo.rpt_STOPsa
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Primary Victims:  Includes intakes with VictimType of Sexual Assault or where abuse history includes sexual violence
	-- Resident victims
    SELECT p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS VictimName, p.EthnicityID,
        xe.Ethnicity, p.Sex, p.DOB, i.EntryDate, AGE = DATEDIFF(year, p.DOB, i.EntryDate), i.AbuserRelationshipID, xi.IntakeType,
        xa.AbuserRelationship, AbuseSexual = CAST(i.AbuseSexual AS BIT), xc.CallSubject AS VictimType, Disability = CAST(CASE 
            WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1 OR i.ChronicHealthCondition = 1
            THEN 1 ELSE 0 END AS BIT),
        Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL),
        LinkedCall = CAST(CASE WHEN ic.CallID IS NULL THEN 0 ELSE 1 END AS BIT)
    FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN xAbuserRelationship xa ON i.AbuserRelationshipID = xa.AbuserRelationshipID
        INNER JOIN xEthnicity xe ON xe.EthnicityID = p.EthnicityID
        INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
        LEFT OUTER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
        LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        INNER JOIN xCallSubject xc ON xc.CallSubjectID = ivt.VictimTypeID
    WHERE (ivt.VictimTypeID = 6 OR i.AbuseSexual = 1)
	    AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
	UNION ALL
	-- Non-Resident victims who received a service
    SELECT p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS VictimName, p.EthnicityID,
        xe.Ethnicity, p.Sex, p.DOB, i.EntryDate, AGE = DATEDIFF(year, p.DOB, i.EntryDate), i.AbuserRelationshipID, xi.IntakeType,
        xa.AbuserRelationship, AbuseSexual = CAST(i.AbuseSexual AS BIT), xc.CallSubject AS VictimType, Disability = CAST(CASE 
            WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1 OR i.ChronicHealthCondition = 1
            THEN 1 ELSE 0 END AS BIT),
        Children = (SELECT COUNT(ChildID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL),
        LinkedCall = CAST(CASE WHEN ic.CallID IS NULL THEN 0 ELSE 1 END AS BIT)
    FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN xAbuserRelationship xa ON i.AbuserRelationshipID = xa.AbuserRelationshipID
        INNER JOIN xEthnicity xe ON xe.EthnicityID = p.EthnicityID
        INNER JOIN xIntakeType xi ON i.IntakeTypeID = xi.IntakeTypeID
        LEFT OUTER JOIN IntakeCalls ic ON i.IntakeID = ic.IntakeID
        LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        INNER JOIN xCallSubject xc ON xc.CallSubjectID = ivt.VictimTypeID
    WHERE (ivt.VictimTypeID = 6 OR i.AbuseSexual = 1)
	    AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
        AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
		AND (SELECT TOP 1 cs.SessionID 
			FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID 
			WHERE ClientID = p.ParticipantID AND ClientTypeID = 1
				AND s.SessionDate BETWEEN @StartDate AND @EndDate) IS NOT NULL
    ORDER BY VictimName, Children DESC;

-- Callers/Walk-ins requesting shelter that were denied
    SELECT x.ReasonDenied, c.CallDate, c.LastName + ', ' + c.FirstName AS Caller
    FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        INNER JOIN xReasonDenied x ON sr.ReasonDeniedID = x.ReasonDeniedID
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND sr.ReasonDeniedID > 0
    ORDER BY ReasonDenied;

-- Hotline Calls; all crisis and info/referral calls
    SELECT COUNT(c.CallID) AS TotalCalls
    FROM Calls c
    WHERE c.CallDate BETWEEN @StartDate AND @EndDate
        AND c.DeletedDate IS NULL
        AND c.CallTypeID < 4;

-- Services to primary victims identified above that are mapped to STOP service types
    SELECT p.ParticipantID, s.SessionID,
        p.LastName + ', ' + p.FirstName AS VictimName,
        sm.GrantorServiceID, gs.GrantorService, ss.ServiceName, s.SessionDate
    FROM Participants p INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
        INNER JOIN Sessions s ON cs.SessionID = s.SessionID
        INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
        INNER JOIN Services ss ON ss.ServiceID = s.ServiceID
        INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
        INNER JOIN GrantorServices gs ON sm.GrantorServiceID = gs.GrantorServiceID AND gs.GrantorID = 8
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND sm.GrantorServiceID BETWEEN 801 AND 811
        AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        AND p.ParticipantID IN
            (
                SELECT DISTINCT p1.ParticipantID
                FROM Intakes i1 INNER JOIN Participants p1 ON i1.ParticipantID = p1.ParticipantID
                    INNER JOIN IntakeVictimType ivt ON i1.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR i1.AbuseSexual = 1)
                    AND i1.EntryDate <= @EndDate AND (i1.ExitDate IS NULL OR i1.ExitDate >= @StartDate)
                    AND i1.DeletedDate IS NULL AND p1.DeletedDate IS NULL
            )
    ORDER BY VictimName, ParticipantID, GrantorServiceID, SessionDate;

-- Bednights for primary victims and children identified above (Crisis/Homeless/Transitional)
    SELECT ParticipantID = 0, ChildID = 0, ClientName = 'Dummy Client', ClientType = 0,
        EntryDate = @StartDate, IntakeType = 'Dummy Intake', IntakeTypeID = 0, Bednights = 0
    UNION ALL
    -- New Participants
    SELECT i.ParticipantID, ChildID = 0, p.LastName + ', ' + p.FirstName AS ClientName,
        ClientType = 1, EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, i.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END
    FROM Intakes i INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE EntryDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR i.AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    UNION ALL
    -- Carryover Participants
    SELECT i.ParticipantID, ChildID = 0, p.LastName + ', ' + p.FirstName AS ClientName, 
        ClientType = 1, EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN i.EntryDate = i.ExitDate THEN 1
            WHEN i.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN i.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, i.ExitDate) END
    FROM Intakes i INNER JOIN xIntakeType x ON
 i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
    WHERE EntryDate < @StartDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR i.AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    UNION ALL
    -- New Children
    SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
        ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
            ELSE DATEDIFF(day, i.EntryDate, i.ExitDate) END
    FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
    WHERE ci.EntryDate BETWEEN @StartDate AND @EndDate
        AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR i.AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    UNION ALL
    -- Carryover Children
    SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
        ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN ci.EntryDate = ci.ExitDate THEN 1
            WHEN ci.ExitDate IS NULL THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            WHEN ci.ExitDate > @EndDate THEN DATEDIFF(day, @StartDate, @EndDate) + 1
            ELSE DATEDIFF(day, @StartDate, ci.ExitDate) END
    FROM ChildIntakes ci INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
    WHERE ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
        AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    UNION ALL
    -- Child Absences for NEW Children
    SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
        ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
            WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) ENd
    FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL ANd i.DeletedDate IS NULL
        AND ci.EntryDate BETWEEN @StartDate ANd @EndDate
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND ca.DateOut BETWEEN @StartDate AND @EndDate
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    UNION ALL
    -- Child Absences for Carryover Children
    SELECT ParticipantID = 0, c.ChildID, c.LastName + ', ' + c.FirstName AS ClientName,
        ClientType = 2, ci.EntryDate, x.IntakeType, i.IntakeTypeID,
        Bednights = CASE
            WHEN ca.DateReturn IS NULL AND ci.ExitDate IS NOT NULL THEN DATEDIFF(day, ci.ExitDate, ca.DateOut)
            WHEN ca.DateReturn IS NULL THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            WHEN ca.DateReturn > @EndDate THEN DATEDIFF(day, @EndDate, ca.DateOut) + 1
            ELSE DATEDIFF(day, ca.DateReturn, ca.DateOut) ENd
    FROM ChildAbsences ca INNER JOIN ChildIntakes ci ON ca.ChildIntakeID = ci.ChildIntakeID
        INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
        INNER JOIN Children c ON ci.ChildID = c.ChildID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE c.DeletedDate IS NULL AND ci.DeletedDate IS NULL ANd i.DeletedDate IS NULL
        AND ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
        AND i.IntakeTypeID IN (1, 2, 3, 5)
        AND ca.DateOut <= @EndDate
        AND (ca.DateReturn IS NULL OR ca.DateReturn > @StartDate)
        AND i.ParticipantID IN 
            (
                SELECT DISTINCT p.ParticipantID
                FROM Intakes i INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
                    LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
                WHERE (ivt.VictimTypeID = 6 OR AbuseSexual = 1)
                    AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
                    AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            )
    ORDER BY ClientType, ClientName;  

rpt_SurveyReportData
CREATE PROCEDURE dbo.rpt_SurveyReportData
	(@StartDate SMALLDATETIME, @EndDate	SMALLDATETIME, @IntakeTypeID INT = 0,
	@SurveyIDs AS dbo.IdTable READONLY)
	AS
	IF @IntakeTypeID = 0
		-- All intake types
		BEGIN

			SELECT qq.Outcome, qq.Question, q.QuestionnaireID, qq.QuestionID, qr.Response, sq.QuestionNumber,
			    qq.MaxRating, q.ControlNumber, q.SurveyID
			FROM Questionnaires q INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
			    INNER JOIN Questions qq ON qr.QuestionID = qq.QuestionID
			    INNER JOIN SurveyQuestions sq ON qq.QuestionID = sq.QuestionID AND sq.SurveyID = q.SurveyID
			WHERE q.SurveyID IN (SELECT ID FROM @SurveyIDs) 
				AND qq.DeletedDate IS NULL 
				AND q.CompletedDate BETWEEN @StartDate AND @EndDate
			ORDER BY sq.QuestionNumber, qq.QuestionID;
			--Narratives
			SELECT sn.NarrativeID, sn.Description, nr.Narrative, q.ControlNumber
			FROM Questionnaires q INNER JOIN NarrativeResponses nr ON q.QuestionnaireID = nr.QuestionnaireID
			    INNER JOIN SurveyNarratives sn ON nr.NarrativeID = sn.NarrativeID AND sn.SurveyID = q.SurveyID
			WHERE q.SurveyID IN (SELECT ID FROM @SurveyIDs)
				AND LEN(RTRIM(Narrative)) > 0 
			    AND q.CompletedDate BETWEEN @StartDate AND @EndDate 
				AND q.DeletedDate IS NULL
			ORDER BY sn.NarrativeID;
		END
	ELSE
		-- Specified Intake types, participants only
		BEGIN
            SELECT qq.Outcome, qq.Question, q.QuestionnaireID, qq.QuestionID, qr.Response, sq.QuestionNumber,
                qq.MaxRating, q.ControlNumber, q.SurveyID
            FROM Questionnaires q INNER JOIN QuestionResponses qr ON q.QuestionnaireID = qr.QuestionnaireID
                INNER JOIN Questions qq ON qr.QuestionID = qq.QuestionID
                INNER JOIN SurveyQuestions sq ON qq.QuestionID = sq.QuestionID AND sq.SurveyID = q.SurveyID
				INNER JOIN Intakes i ON i.IntakeID = q.IntakeID AND q.ClientTypeID = 1
            WHERE q.SurveyID IN (SELECT ID FROM @SurveyIDs)
				AND i.IntakeTypeID = @IntakeTypeID
                AND qq.DeletedDate IS NULL 
				AND q.CompletedDate BETWEEN @StartDate AND @EndDate
            ORDER BY QuestionNumber, sq.QuestionID;
			-- Narratives
            SELECT sn.NarrativeID, sn.Description, nr.Narrative, q.ControlNumber
            FROM Questionnaires q INNER JOIN NarrativeResponses nr ON q.QuestionnaireID = nr.QuestionnaireID
                INNER JOIN SurveyNarratives sn ON nr.NarrativeID = sn.NarrativeID AND sn.SurveyID = q.SurveyID
				INNER JOIN Intakes i ON i.IntakeID = q.IntakeID AND q.ClientTypeID = 1
            WHERE q.SurveyID IN (SELECT ID FROM @SurveyIDs) 
				AND LEN(RTRIM(Narrative)) > 0 
                AND q.CompletedDate BETWEEN @StartDate AND @EndDate 
				AND q.DeletedDate IS NULL
                AND i.IntakeTypeID = @IntakeTypeID
            ORDER BY sn.NarrativeID;  
		END

rpt_TangibleGoods
CREATE PROCEDURE dbo.rpt_TangibleGoods
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT x.GoodType, tg.Quantity
    FROM TangibleGoods tg INNER JOIN xGoodType x ON tg.GoodTypeID = x.GoodTypeID
        INNER JOIN Sessions s ON tg.SessionID = s.SessionID
    WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL
    ORDER BY x.GoodType;

rpt_TaskStatus
CREATE PROCEDURE dbo.rpt_TaskStatus
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT i.ShelterID, s.ShelterName, xit.IntakeType, p.ParticipantID, p.LastName + ', ' + p.FirstName + ' ' + MI AS FullName,
        t.Task, i.EntryDate, DATEADD(day, t.DaysToComplete, i.EntryDate) AS DueDate, it.CompletedDate, i.IntakeTypeID
    FROM Intakes i INNER JOIN Tasks t ON i.IntakeTypeID = t.IntakeTypeID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
        INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
        INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xIntakeType xit ON t.IntakeTypeID = xit.IntakeTypeID
        LEFT OUTER JOIN IntakeTasks it ON it.IntakeID = i.IntakeID AND t.TaskID = it.TaskID
    WHERE i.ExitDate IS NULL AND t.IsCurrent = 1 AND @StartDate < i.EntryDate
        AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND t.DeletedDate IS NULL
    ORDER BY s.ShelterName, t.IntakeTypeID, FullName, DaysToComplete;

rpt_TrainingSessions
CREATE PROCEDURE dbo.rpt_TrainingSessions
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- Main portion of report
	SELECT ts.SessionID, Credential AS Topic, SessionDate, SessionHours, s.LastName + ', ' + s.FirstName AS StaffName, ts.SessionNote, ts.Facilitators
    FROM Credentials c INNER JOIN TrainingSessions ts ON c.CredentialID = ts.SubjectID
		INNER JOIN StaffTraining st ON ts.SessionID = st.SessionID INNER JOIN Staff s ON st.StaffID = s.StaffID
    WHERE ts.SessionDate BETWEEN @StartDate AND @EndDate AND ts.DeletedDate IS NULL AND s.DeletedDate IS NULL
    ORDER BY Topic, SessionDate, SessionID, StaffName;
    -- Number of training sessions
	SELECT Count(Distinct ts.SessionID) AS NumberPresentations, Count(Distinct StaffID) AS NumberStaff,
		Sum(ts.SessionHours) AS StaffHours FROM StaffTraining st INNER JOIN TrainingSessions ts ON st.SessionID = ts.SessionID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate AND DeletedDate IS NULL;
	SELECT DISTINCT(SessionNote) FROM TrainingSessions
    WHERE SessionDate BETWEEN @StartDate AND @EndDate AND DeletedDate IS NULL;

rpt_TripLog
CREATE PROCEDURE dbo.rpt_TripLog
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    SELECT COUNT(TripID) AS NumberClients, Destination, OneWay, MilesOneWay,
        xt.Purpose, County, ISNULL(Vehicle, '') AS Vehicle, SessionDate AS TripDate
    FROM [Sessions] s INNER JOIN Trips t ON s.SessionID = t.TripID
        INNER JOIN xTripPurpose xt ON t.PurposeID = xt.PurposeID
        INNER JOIN xCounty xc ON t.DestinationCountyID = xc.CountyID
        INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
        LEFT OUTER JOIN Vehicles v ON t.VehicleID = v.VehicleID
    WHERE SessionDate BETWEEN @StartDate AND @EndDate
        AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
    GROUP BY xt.Purpose, TripID, SessionDate, Destination, OneWay, MilesOneWay, County, Vehicle
    ORDER BY xt.Purpose, TripDate;

rpt_VictimsServed
CREATE PROCEDURE dbo.rpt_VictimsServed
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
	-- Callers:  Call subject is victim type (3 - 99);
    SELECT CallSubject, COUNT(c.CallSubjectID) AS Victims, SUM(NumberChildren) AS Children,
        COUNT(sr.RequestOutcomeID) AS ShelterRequests, COUNT(ic.IntakeID) AS Intakes,
        COUNT(sr1.RequestOutcomeID) AS NoShows, COUNT(sr2.RequestOutcomeID) AS NotSheltered
    FROM xCallSubject x INNER JOIN Calls c ON x.CallSubjectID = c.CallSubjectID
        LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
        LEFT OUTER JOIN ShelterRequests sr ON c.CallID = sr.CallID
        LEFT OUTER JOIN ShelterRequests sr1 ON c.CallID = sr1.CallID AND sr1.RequestOutcomeID = 7
        LEFT OUTER JOIN ShelterRequests sr2 ON c.CallID = sr2.CallID AND sr2.RequestOutcomeID BETWEEN 2 AND 6
    WHERE CallDate BETWEEN @StartDate AND @EndDate
        AND c.CallTypeID < 4
        AND c.CallSubjectID BETWEEN 3 AND 99
        AND c.DeletedDate IS NULL
    GROUP BY CallSubject
    ORDER BY CallSubject;
	-- All Crisis and Non-Resident DV intakes, including related child intakes,
	-- and any other intakes (except homeless) where victim type is specified
    -- New Crisis Clients
    SELECT SortOrder = -2, IntakeType = 'Crisis', Intake = 'New', ivt.VictimTypeID,
        x.CallSubject AS VictimType, i.ParticipantID AS NewParticipantID, ci.ChildID AS NewChildID,
        OldParticipantID = NULL, OldChildID = NULL
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID = 1 AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL
    UNION ALL
    -- CarryOver Crisis Clients
    SELECT SortOrder = -1, IntakeType = 'Crisis', Intake = 'Continuing', ivt.VictimTypeID,
        x.CallSubject AS VictimType, NewParticipantID = NULL, NewChildID = NULL,
        i.ParticipantID AS OldParticipantID, ci.ChildID AS OldChildID
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID = 1 AND i.EntryDate < @StartDate 
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
    UNION ALL
    -- New Non-Resident DV Clients
    SELECT SortOrder = 0, IntakeType = 'Non-Resident DV', Intake = 'New', ivt.VictimTypeID,
        x.CallSubject AS VictimType, i.ParticipantID AS NewParticipantID, ci.ChildID AS NewChildID,
        OldParticipantID = NULL, OldChildID = NULL
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID = 4 AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL
    UNION ALL
    -- CarryOver Non-Resident DV Clients
    SELECT SortOrder = 1, IntakeType = 'Non-Resident DV', Intake = 'Continuing', ivt.VictimTypeID,
        x.CallSubject AS VictimType, NewParticipantID = NULL, NewChildID = NULL,
        i.ParticipantID AS OldParticipantID, ci.ChildID AS OldChildID
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID = 4 AND i.EntryDate < @StartDate 
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
    UNION ALL
    -- All other New intake types
    SELECT xit.IntakeTypeID AS SortOrder, IntakeType = xit.IntakeType, Intake = 'Continuing',
        ivt.VictimTypeID, x.CallSubject AS VictimType, i.ParticipantID AS NewParticipantID,
        ci.ChildID AS NewChildID, OldParticipantID = NULL, OldChildID = NULL
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        INNER JOIN xIntakeType xit ON i.IntakeTypeID = xit.IntakeTypeID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID NOT IN (1, 4) AND i.EntryDate BETWEEN @StartDate AND @EndDate
        AND i.DeletedDate IS NULL
    UNION ALL
    -- All other Carrrover Intake Types
    SELECT xit.IntakeTypeID AS SortOrder, IntakeType = xit.IntakeType, Intake = 'Continuing',
        ivt.VictimTypeID, x.CallSubject AS VictimType, NewParticipantID = NULL,
        NewChildID = NULL, i.ParticipantID AS OldParticipantID, ci.ChildID AS OldChildID
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
        INNER JOIN xIntakeType xit ON i.IntakeTypeID = xit.IntakeTypeID
        LEFT OUTER JOIN ChildIntakes ci ON i.IntakeID = ci.IntakeID
    WHERE i.IntakeTypeID NOT IN (1, 4) AND  i.EntryDate < @StartDate 
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
    ORDER BY SortOrder;
	-- Clients with multiple victim types listed in their intake
    SELECT i.IntakeID, x.CallSubject AS VictimType,
        New = CAST(CASE WHEN i.EntryDate >= @StartDate THEN 1 ELSE 0 END AS BIT)
    FROM Intakes i INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        INNER JOIN xCallSubject x ON ivt.VictimTypeID = x.CallSubjectID
    WHERE i.EntryDate <= @EndDate
        AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL 
        AND i.IntakeID  IN
            (SELECT IntakeID FROM IntakeVictimType
            GROUP BY IntakeID
            HAVING COUNT(IntakeID) > 1)
    ORDER BY IntakeID;

rpt_VOCA
CREATE PROCEDURE rpt_VOCA
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
    -- The clients retrieved in the victims and services queries are in four groups:
    -- Participants, Children, Community Members, and Callers
    -- The retrieved records will have a unique Client ID as follows:
    -- ParticipantID, ChildID + 1000000, MemberID + 2000000, CallID + 3000000

    -- TOTAL VICTIMS SERVED
    -- Includes all victims served during the report period.
    -- Victims with more than one victim type will have a row for each type, otherwise the rows are distinct (UNION, not UNION ALL)
    -- Subsequent occurrences for the same client will be marked as duplicates so the report
    -- can filter them out of totals.
        DECLARE @False BIT SET @False = CAST(0 AS BIT);

        -- Resident Participant Victims with intakes in VOCA grant related shelter during report period
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, p.ParticipantID AS ClientID,
            Deaf = CAST(i.Deaf AS BIT), 
            Homeless = CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = CAST(p.LGBT AS BIT),
            Veteran = CAST(p.Veteran AS BIT),
            LimitedEnglish = CAST(CASE WHEN i.LanguageID > 2 THEN 1 ELSE 0 END AS BIT),
            Disability = CAST(CASE WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1
                OR i.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, 
            i.AbusedAsChild, ChildPhysicalAbuse = @False, ChildSexualAbuse = @False
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID IN (1, 2, 3, 5)
		UNION
		-- Non-Resident Participant Victims with intakes in VOCA grant related shelter during report period
		-- who received a VOCA-related service during the period
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, p.ParticipantID AS ClientID,
            Deaf = CAST(i.Deaf AS BIT), 
            Homeless = CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = CAST(p.LGBT AS BIT),
            Veteran = CAST(p.Veteran AS BIT),
            LimitedEnglish = CAST(CASE WHEN i.LanguageID > 2 THEN 1 ELSE 0 END AS BIT),
            Disability = CAST(CASE WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1
                OR i.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, 
            i.AbusedAsChild, ChildPhysicalAbuse = @False, ChildSexualAbuse = @False
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
			AND (SELECT TOP 1 cs.SessionID
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID
					INNER JOIN ServiceFocus sf ON s.FocusID = sf.FocusID AND s.ServiceID = sf.ServiceID
					INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
				WHERE cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
					AND s.SessionDate BETWEEN @StartDate AND @EndDate
					AND sm.GrantorID = 9) IS NOT NULL
        UNION
        -- Resident Child Victims with intakes in VOCA grant related shelter during report period
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, ci.ChildID + 1000000 AS ClientID,
            Deaf = @False, Homeless =CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = @False, Veteran = @False, LimitedEnglish = @False,
            Disability = CAST(CASE WHEN ci.MentalIllness = 1 OR ci.PhysDisability = 1 OR ci.DevDisability = 1 OR ci.HIVAIDS = 1
                OR ci.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName,
            AbusedAsChild = @False, ci.AbusePhysical AS ChildPhysicalAbuse, ci.AbuseSexual AS ChildSexualAbuse
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID IN (1, 2, 3, 5)
		UNION
        -- Non-Resident Child Victims with intakes in VOCA grant related shelter during report period
		-- who received a VOCA-related service
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, ci.ChildID + 1000000 AS ClientID,
            Deaf = @False, Homeless =CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = @False, Veteran = @False, LimitedEnglish = @False,
            Disability = CAST(CASE WHEN ci.MentalIllness = 1 OR ci.PhysDisability = 1 OR ci.DevDisability = 1 OR ci.HIVAIDS = 1
                OR ci.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName,
            AbusedAsChild = @False, ci.AbusePhysical AS ChildPhysicalAbuse, ci.AbuseSexual AS ChildSexualAbuse
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL AND ci.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
			AND (SELECT TOP 1 cs.SessionID
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID
					INNER JOIN ServiceFocus sf ON s.FocusID = sf.FocusID AND s.ServiceID = sf.ServiceID
					INNER JOIN Serv
iceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
				WHERE cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
					AND s.SessionDate BETWEEN @StartDate AND @EndDate
					AND sm.GrantorID = 9) IS NOT NULL
        UNION
        -- Participant victims served by grant-related PROGRAM
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, p.ParticipantID AS ClientID,
            Deaf = CAST(i.Deaf AS BIT),
            Homeless = CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = CAST(p.LGBT AS BIT),
            Veteran = CAST(p.Veteran AS BIT),
            LimitedEnglish = CAST(CASE WHEN i.LanguageID > 2 THEN 1 ELSE 0 END AS BIT),
            Disability = CAST(CASE WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1
                OR i.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName,
            i.AbusedAsChild, ChildPhysicalAbuse = @False, ChildSexualAbuse = @False
        FROM IntakeVictimType ivt INNER JOIN Intakes i ON ivt.IntakeID = i.IntakeID
            INNER JOIN	Participants p ON p.ParticipantID = i.ParticipantID
            INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate and @EndDate
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION 
        -- Child victims served by grant-related PROGRAM
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, ci.ChildID + 1000000 AS ClientID,
            Deaf = @False, Homeless =CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = @False, Veteran = @False, LimitedEnglish = @False,
            Disability = CAST(CASE WHEN ci.MentalIllness = 1 OR ci.PhysDisability = 1 OR ci.DevDisability = 1 OR ci.HIVAIDS = 1
                OR ci.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName,
            AbusedAsChild = @False, ci.AbusePhysical AS ChildPhysicalAbuse, ci.AbuseSexual AS ChildSexualAbuse
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN ClientSessions cs ON cs.ClientID = ci.ChildID AND cs.ClientTypeID = 2
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate and @EndDate
            AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION
        -- Community member victims served by VOCA grant-related PROGRAM
        SELECT cm.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, cm.MemberID + 2000000 AS ClientID,
            Deaf = @False, Homeless = @False, Immigrant = @False, LGBT = @False, Veteran = @False,
            LimitedEnglish = @False, Disability = @False, IsDuplicate = @False,
            cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName,
            @False, @False, @False
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE cm.VictimTypeID BETWEEN 3 AND 99
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION
        -- Caller victims served by grant-related SHELTER hotline (no linked intake)
        SELECT c.CallSubjectID AS VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, c.CallID + 3000000 AS ClientID,
            Deaf = @False, Homeless = @False, Immigrant = @False, LGBT = @False, Veteran = @False,
            LimitedEnglish = @False, Disability = @False, IsDuplicate = @False,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName,
            @False, @False, @False
        FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
        WHERE CallDate BETWEEN @StartDate AND @EndDate
            AND CallSubjectID BETWEEN 3 AND 99
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND c.CallTypeID < 4
            AND ic.IntakeID IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION
        -- Participant victims served by grant-funded staff
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, p.ParticipantID AS ClientID,
            Deaf = CAST(i.Deaf AS BIT),
            Homeless = CAST(p.ChronicallyHomeless AS BIT),
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = CAST(p.LGBT AS BIT),
            Veteran = CAST(p.Veteran AS BIT),
            LimitedEnglish = CAST(CASE WHEN i.LanguageID > 2 THEN 1 ELSE 0 END AS BIT),
            Disability = CAST(CASE WHEN i.MentalIllness = 1 OR i.PhysDisability = 1 OR i.DevDisability = 1 OR i.HIVAIDS = 1
                OR i.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName,
            i.AbusedAsChild, ChildPhysicalAbuse = @False, ChildSexualAbuse = @False
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN ClientSessions cs ON i.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION
        -- Child victims served by grant-funded staff
        SELECT ivt.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, ci.ChildID + 1000000 AS ClientID,


            Deaf = @False, Homeless =CAST(p.ChronicallyHomeless AS BIT), 
            Immigrant = CAST(CASE WHEN i.CitizenshipID > 2 THEN 1 ELSE 0 END AS BIT),
            LGBT = @False, Veteran = @False, LimitedEnglish = @False,
            Disability = CAST(CASE WHEN ci.MentalIllness = 1 OR ci.PhysDisability = 1 OR ci.DevDisability = 1 OR ci.HIVAIDS = 1
                OR ci.ChronicHealthCondition = 1 THEN 1 ELSE 0 END AS BIT), IsDuplicate = @False,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName,
            AbusedAsChild = @False, ci.AbusePhysical AS ChildPhysicalAbuse, ci.AbuseSexual AS ChildSexualAbuse
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN ClientSessions cs ON cs.ClientID = ci.ChildID AND cs.ClientTypeID = 2
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON ss.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION
        -- Community member victims served by grant-related staff
        SELECT cm.VictimTypeID, g.GrantID, g.Prorate, g.ContractNumber, cm.MemberID + 2000000 AS ClientID,
            Deaf = @False, Homeless = @False, Immigrant = @False, LGBT = @False, Veteran = @False,
            LimitedEnglish = @False, Disability = @False, IsDuplicate = @False,
            cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName,
            @False, @False, @False
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate AND @EndDate
            AND cm.VictimTypeID BETWEEN 3 AND 99
            AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        ORDER BY g.GrantID, ClientID;

    -- NEW VICTIMS
        -- ALL CLIENTS DURING GRANT PERIOD BEFORE REPORT END
        -- THOSE WITH EVENT DATES BEFORE THE REPORT START WILL BE FILTERED
        -- OUT LATER

        -- Resident Participant Victims with intakes in VOCA grant related shelter during grant period
        SELECT g.GrantID, g.ContractNumber, g.Prorate, p.ParticipantID AS ClientID, p.EthnicityID, p.Sex,
            Age = DATEDIFF(year, p.DOB, i.EntryDate), EventDate = i.EntryDate, i.EntryDate, p.DOB,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= g.GrantStart)
            AND ivt.VictimTypeID IS NOT NULL
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID IN (1, 2, 3, 5)
		UNION ALL
        -- Non-Resident Participant Victims with intakes in VOCA grant related shelter during grant period
		-- who received a VOCA-related service during the period
        SELECT g.GrantID, g.ContractNumber, g.Prorate, p.ParticipantID AS ClientID, p.EthnicityID, p.Sex,
            Age = DATEDIFF(year, p.DOB, i.EntryDate), EventDate = i.EntryDate, i.EntryDate, p.DOB,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= g.GrantStart)
            AND ivt.VictimTypeID IS NOT NULL
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
			AND (SELECT TOP 1 cs.SessionID
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID
					INNER JOIN ServiceFocus sf ON s.FocusID = sf.FocusID AND s.ServiceID = sf.ServiceID
					INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
				WHERE cs.ClientID = p.ParticipantID AND cs.ClientTypeID = 1
					AND s.SessionDate BETWEEN @StartDate AND @EndDate
					AND sm.GrantorID = 9) IS NOT NULL
        UNION ALL
        -- Resident Child Victims with intakes in VOCA grant-related shelters during grant period
        SELECT g.GrantID, g.ContractNumber, g.Prorate, c.ChildID + 1000000 AS ClientID, c.EthnicityID, c.Sex,
            Age = DATEDIFF(year, c.DOB, ci.EntryDate), EventDate = ci.EntryDate, ci.EntryDate, c.DOB,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= g.GrantStart)
            AND ivt.VictimTypeID IS NOT NULL
            AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
			AND i.IntakeTypeID IN (1, 2, 3, 5)
		UNION ALL
        -- Non-Resident Child Victims with intakes in VOCA grant-related shelters during grant period
		-- who received a VOCA-related service
        SELECT g.GrantID, g.ContractNumber, g.Prorate, c.ChildID + 1000000 AS ClientID, c.EthnicityID, c.Sex,
            Age = DATEDIFF(year, c.DOB, ci.EntryDate), EventDate = ci.EntryDate, ci.EntryDate, c.DOB,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= g.GrantStart)
            AND ivt.VictimTypeID IS NOT NULL
            AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.Grant
Start AND g.GrantEnd
			AND i.IntakeTypeID NOT IN (1, 2, 3, 5)
			AND (SELECT TOP 1 cs.SessionID
				FROM ClientSessions cs INNER JOIN Sessions s ON cs.SessionID = s.SessionID
					INNER JOIN ServiceFocus sf ON s.FocusID = sf.FocusID AND s.ServiceID = sf.ServiceID
					INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
				WHERE cs.ClientID = c.ChildID AND cs.ClientTypeID = 2
					AND s.SessionDate BETWEEN @StartDate AND @EndDate
					AND sm.GrantorID = 9) IS NOT NULL
        UNION ALL
        -- Caller Victims served by VOCA grant-realted Shelter hotline (no linked intake)
        SELECT g.GrantID, g.ContractNumber, g.Prorate, c.CallID + 3000000 AS ClientID, EthnicityID = 1, c.Sex,
            Age = -1, c.CallDate AS EventDate, c.CallDate, DOB = NULL,
            c.LastName + ', ' + c.FirstName AS ClientName
        FROM Calls c INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeCalls ic ON c.CallID = ic.CallID
        WHERE c.CallDate BETWEEN @StartDate AND @EndDate
            AND c.CallTypeID < 4 AND c.CallSubjectID BETWEEN 3 AND 99
            AND ic.IntakeID IS NULL
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Participant victims served by VOCA grant-related Program
        SELECT g.GrantID, g.ContractNumber, g.Prorate, p.ParticipantID AS ClientID, p.EthnicityID, p.Sex,
            Age = DATEDIFF(year, p.DOB, i.EntryDate), EventDate = i.EntryDate, i.EntryDate, p.DOB,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
        FROM IntakeVictimType ivt INNER JOIN Intakes i ON ivt.IntakeID = i.IntakeID
            INNER JOIN	Participants p ON p.ParticipantID = i.ParticipantID
            INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN g.GrantStart AND @EndDate
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= g.GrantStart)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Child victims served by VOCA grant-related Program
        SELECT g.GrantID, g.ContractNumber, g.Prorate, c.ChildID + 1000000 AS ClientID, c.EthnicityID, c.Sex,
            Age = DATEDIFF(year, c.DOB, ci.EntryDate), EventDate = ci.EntryDate, ci.EntryDate, c.DOB,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
        FROM Children c INNER JOIN 	ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
            INNER JOIN ClientSessions cs ON cs.ClientID = ci.ChildID AND cs.ClientTypeID = 2
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE s.SessionDate BETWEEN @StartDate and @EndDate
            AND ci.EntryDate <= @EndDate AND (ci.ExitDate IS NULL OR ci.ExitDate >= @StartDate)
            AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Community member victims served by VOCA grant-related Program
        SELECT g.GrantID, g.ContractNumber, g.Prorate, cm.MemberID + 2000000 AS ClientID, cm.EthnicityID, cm.Sex,
            Age = CASE WHEN cm.DOB IS NULL THEN -1 ELSE DATEDIFF(year, cm.DOB, s.SessionDate) END, EventDate = s.SessionDate,
            s.SessionDate AS EventDate, cm.DOB,
            cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE cm.VictimTypeID BETWEEN 3 AND 99
            AND s.SessionDate BETWEEN g.GrantStart AND @EndDate
            AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Participant victims served by grant-related staff
        SELECT g.GrantID, g.ContractNumber, g.Prorate, p.ParticipantID AS ClientID, p.EthnicityID, p.Sex,
            Age = DATEDIFF(year, p.DOB, i.EntryDate), s.SessionDate AS EventDate, i.EntryDate, p.DOB,
            p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN ClientSessions cs ON p.ParticipantID = cs.ClientID AND cs.ClientTypeID = 1
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL
            AND s.SessionDate BETWEEN g.GrantStart AND @EndDate
            AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND s.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Child victims served by grant-related staff
        SELECT g.GrantID, g.ContractNumber, g.Prorate, c.ChildID + 1000000 AS ClientID, c.EthnicityID, c.Sex,
            Age = DATEDIFF(year, c.DOB, ci.EntryDate), EventDate = s.SessionDate, ci.EntryDate, c.DOB,
            c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN ClientSessions cs ON c.ChildID = cs.ClientID AND cs.ClientTypeID = 2
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON ivt.IntakeID = i.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL
            AND s.SessionDate BETWEEN g.GrantStart AND @EndDate
            AND c.DeletedDate IS NULL AND ci.DeletedDate IS NULL AND i.DeletedDate IS NULL
            AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Community member victims served by grant-related staff
        SELECT g.GrantID, g.ContractNumber, g.Prorate, cm.MemberID + 2000000 AS ClinetID, cm.EthnicityID, cm.Sex,
            Age = CASE WHEN cm.DOB IS NULL THEN -1 ELSE DATEDIFF(year, cm.DOB, s.SessionDate) END, EventDate = s.SessionDate,
            s.SessionDate AS EntryDate, cm.DOB,
 
           cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN Sessions s ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON s.SessionID = ss.SessionID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE cm.VictimTypeID BETWEEN 3 AND 99
            AND s.SessionDate BETWEEN g.GrantStart AND @EndDate
            AND cm.DeletedDate IS NULL AND s.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9 AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        ORDER BY g.GrantID, ClientID, EventDate; 

    -- DIRECT SERVICES
        -- Services to Participant victims served by VOCA grant-related SHELTER
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs ON g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm on gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN [Sessions] s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN Intakes i ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Services to Participant victims served by VOCA grant-related PROGRAM
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs ON g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm on gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN [Sessions] s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN Intakes i ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Services to Participant victims served by VOCA grant-related STAFF
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID,  g.ContractNumber, g.Prorate, sm.GrantorServiceID, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs ON g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            INNER JOIN [Sessions] s ON sf.ServiceID = s.ServiceID AND sf.FocusID = s.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON cs.SessionID = ss.SessionID
            INNER JOIN Intakes i ON i.IntakeID = cs.IntakeID AND cs.ClientTypeID = 1
            INNER JOIN Participants p ON i.ParticipantID = p.ParticipantID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 and 932
            AND @StartDate BETWEEN g.GrantStart and g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate and @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL and s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
        UNION ALL
        -- Services to Community Member victims served by VOCA grant-related PROGRAM
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, cm.MemberID + 3000000 AS ClientID,
            ClientType = 1, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
            INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN GrantorServices gs ON sm.GrantorServiceID = gs.GrantorServiceID
            INNER JOIN Grants g ON gs.GrantorID = g.GrantorID
            INNER JOIN GrantTargets gt ON gt.GrantID = g.GrantID AND gt.TargetTypeID = 2 AND gt.TargetID = s.ProgramID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND cm.VictimTypeID BETWEEN 3 AND 99
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Services to Community Member victims served by VOCA grant-related STAFF
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, cm.MemberID + 3000000 AS ClientID,
            ClientType = 1, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM CommunityMembers cm INNER JOIN ClientSessions cs ON cm.MemberID = cs.ClientID AND cs.ClientTypeID = 4
            INNER JOIN [Sessions] s ON cs.SessionID = s.SessionID
        --    INNER JOIN ServiceMap sm ON s.ServiceID = sm.ServiceID
            INNER JOIN ServiceFocus sf ON s.ServiceID = sf.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ServiceMap sm ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN StaffSessions ss ON cs.SessionID = ss.SessionID
            INNER JOIN GrantorServices gs ON s
m.GrantorServiceID = gs.GrantorServiceID
            INNER JOIN Grants g ON gs.GrantorID = g.GrantorID
            INNER JOIN GrantTargets gt ON gt.GrantID = g.GrantID AND gt.TargetTypeID = 4 AND gt.TargetID = ss.StaffID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND cm.VictimTypeID BETWEEN 3 AND 99
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
        UNION ALL
        -- Services to Child victims served by VOCA grant-related SHELTER
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs on g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN [Sessions] s on sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
            INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Service to Child victims served by VOCA grant-related PROGRAM
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs on g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
        --    INNER JOIN [Sessions] s on sm.ServiceID = s.ServiceID
            INNER JOIN ServiceFocus sf ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN [Sessions] s on sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
            INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN GrantTargets gt ON s.ProgramID = gt.TargetID AND gt.TargetTypeID = 2 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Service to Child victims served by VOCA grant-related STAFF
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, s.SessionDate AS EventDate, s.SessionID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs on g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
        --    INNER JOIN [Sessions] s on sm.ServiceID = s.ServiceID
            INNER JOIN ServiceFocus sf ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN [Sessions] s on sf.ServiceID = s.ServiceID AND s.FocusID = sf.FocusID
            INNER JOIN ClientSessions cs ON cs.SessionID = s.SessionID
            INNER JOIN StaffSessions ss ON cs.SessionID = ss.SessionID
            INNER JOIN ChildIntakes ci ON cs.IntakeID = ci.ChildIntakeID AND cs.ClientTypeID = 2
            INNER JOIN Intakes i ON i.IntakeID = ci.IntakeID
            INNER JOIN Children c ON ci.ChildID = c.ChildID
            INNER JOIN GrantTargets gt ON ss.StaffID = gt.TargetID AND gt.TargetTypeID = 4 AND gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND s.SessionDate BETWEEN @StartDate AND @EndDate
            AND ivt.VictimTypeID IS NOT NULL
            AND g.DeletedDate IS NULL AND s.DeletedDate IS NULL AND cs.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart ANd g.GrantEnd
        UNION ALL
        -- Services provided via Hotline mapped to VOCA grant services and hotline linked to VOCA shelter
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, c.CallID + 2000000 AS ClientID,
            ClientType = 3, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, c.CallDate AS EventDate, c.CallID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs ON g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID =sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN CallServices cs ON sf.ServiceID = cs.ServiceID AND sf.FocusID = cs.FocusID
            INNER JOIN Calls c ON cs.CallID = c.CallID
            INNER JOIN GrantTargets gt ON gt.GrantID = g.GrantID AND gt.TargetTypeID = 1 AND gt.TargetID = c.ShelterID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND c.CallSubjectID BETWEEN 3 AND 99
            AND c.CallDate BETWEEN @StartDate AND @EndDate
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
        UNION ALL
        -- Services provided via Hotline where the Program is linked to VOCA grant
        -- and the service is mapped to VOCA grant services
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, sm.GrantorServiceID, c.CallID + 2000000 AS ClientID,
            ClientType = 3, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, c.CallDate AS EventDate, c.CallID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantorServices gs ON g.GrantorID = gs.GrantorID
            INNER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
            INNER JOIN ServiceFocus sf ON sf.ServiceFocusID = sm.ServiceFocusID
            INNER JOIN CallServices cs ON sf.ServiceID = cs.ServiceID AND sf.FocusID = cs.FocusID
            INNER JOIN Calls c ON cs.CallID = c.CallID
            INNER JOIN GrantTargets gt ON gt.GrantID = g.GrantID AND gt.TargetTypeID = 2 AND gt.TargetID = cs.Pr
ogramID
        WHERE g.GrantorID = 9 AND gs.GrantorServiceID BETWEEN 901 AND 932
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND c.CallSubjectID BETWEEN 3 AND 99
            AND c.CallDate BETWEEN @StartDate AND @EndDate
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL  
        UNION ALL
        -- Info/Referral calls provided via Hotline mapped to VOCA grant shelter, 
        -- reported as Referral to other services, supports, and resources (936)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, c.CallID + 2000000 AS ClientID,
            ClientType = 3, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, c.CallDate AS EventDate, c.CallID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID
            INNER JOIN Calls c ON gt.TargetID = c.ShelterID and gt.TargetTypeID = 1
            LEFT OUTER JOIN IntakeCalls ic on c.CallID = ic.CallID
        WHERE CallDate BETWEEN @StartDate And @EndDate 
            AND CallSubjectID BETWEEN 3 AND 99
            AND CallTypeID = 2 AND ic.CallID IS NULL
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Crisis calls NOT linked to an intake, reported as Hotline/crisis line counseling (932)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 932, c.CallID + 2000000 AS ClientID,
            ClientType = 3, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, c.CallDate AS EventDate, c.CallID AS EventID,
            ServiceUnits = 1
        FROM Grants g INNER JOIN GrantTargets gt ON g.GrantID = gt.GrantID
            INNER JOIN Calls c ON gt.TargetID = c.ShelterID and gt.TargetTypeID = 1
            LEFT OUTER JOIN IntakeCalls ic on c.CallID = ic.CallID
        WHERE CallDate BETWEEN @StartDate And @EndDate 
            AND CallSubjectID BETWEEN 3 AND 99
            AND CallTypeID IN (1, 3) AND ic.CallID IS NULL
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant referrals to victim service programs (935)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 935, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Participants p INNER JOIN Referrals r ON p.ParticipantID = r.ClientID AND r.ClientTypeID = 1
            INNER JOIN Intakes i ON r.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate ANd @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant referrals to other services, supports, and resources (936)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Participants p INNER JOIN Referrals r ON p.ParticipantID = r.ClientID AND r.ClientTypeID = 1
            INNER JOIN Intakes i ON r.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID NOT IN (8, 9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate ANd @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Child referrals to victim service programs (935)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 935, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Referrals r ON ci.ChildIntakeID = r.IntakeID AND r.ClientTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND c.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Child referrals to other services, supports, and resources (936)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Referrals r ON ci.ChildIntakeID = r.IntakeID AND r.ClientTypeID = 2
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID NOT IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND c.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant victims provided emergency shelter in VOCA grant-related shelter (933)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 933, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, i.EntryDate AS EventDate, i.IntakeID AS EventID,
            ServiceUnits = CASE
                WHEN i.EntryDate = i.ExitDate THEN 1
                WHEN EntryDate >= @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, EntryDate, ExitDate)
                WHEN EntryDate < @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ExitDate)
                WHEN EntryDate >= @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, EntryDate, @EndDate) + 1


                WHEN EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                END
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND i.IntakeTypeID IN (1, 3, 5)
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant victims provided transitional shelter in VOCA grant-related shelter (934)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 934, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI AS ClientName, i.EntryDate AS EventDate, i.IntakeID AS EventID,
            ServiceUnits = CASE
                WHEN i.EntryDate = i.ExitDate THEN 1
                WHEN EntryDate >= @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, EntryDate, ExitDate)
                WHEN EntryDate < @StartDate AND ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ExitDate)
                WHEN EntryDate >= @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, EntryDate, @EndDate) + 1
                WHEN EntryDate < @StartDate AND (ExitDate IS NULL OR ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                END
        FROM Participants p INNER JOIN Intakes i ON p.ParticipantID = i.ParticipantID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND i.IntakeTypeID = 2
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND p.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Child victims provided emergency shelter in VOCA grant-related shelter (933)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 933, c.ChildID + 1000000 AS ClientID,
            ClientType = 2, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, i.EntryDate AS EventDate, ci.ChildIntakeID AS EventID,
            ServiceUnits = CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.EntryDate >= @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, ci.EntryDate, ci.ExitDate)
                WHEN ci.EntryDate < @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ci.ExitDate)
                WHEN ci.EntryDate >= @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                WHEN ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                END
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND i.IntakeTypeID IN (1, 3, 5)
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Child victims provided transitional shelter in VOCA grant-related shelter (934)
        SELECT ByShelter = CAST(1 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 934, c.ChildID + 1000000 AS ClientID,
            ClientType = 2, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, i.EntryDate AS EventDate, ci.ChildIntakeID AS EventID,
            ServiceUnits = CASE
                WHEN ci.EntryDate = ci.ExitDate THEN 1
                WHEN ci.EntryDate >= @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, ci.EntryDate, ci.ExitDate)
                WHEN ci.EntryDate < @StartDate AND ci.ExitDate <= @EndDate THEN DATEDIFF(day, @StartDate, ci.ExitDate)
                WHEN ci.EntryDate >= @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, ci.EntryDate, @EndDate) + 1
                WHEN ci.EntryDate < @StartDate AND (ci.ExitDate IS NULL OR ci.ExitDate > @EndDate) THEN DATEDIFF(day, @StartDate, @EndDate) + 1
                END
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN GrantTargets gt ON i.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND i.IntakeTypeID = 2
            AND i.EntryDate <= @EndDate AND (i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
            AND c.DeletedDate IS NULL AND i.DeletedDate IS NULL AND g.DeletedDate IS NULL
            AND g.GrantorID = 9
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant referrals to victim services programs by grant-funded staff (935)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 935, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI as ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Participants p INNER JOIN Referrals r ON p.ParticipantID =r.ClientID AND r.ClientTypeID = 1
            INNER JOIN Intakes i ON r.IntakeID = i.IntakeID
            INNER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON gt.TargetID = sr.StaffID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON g.GrantID = gt.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Participant referrals to other services/suports/resources by grant-funded staff (936)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, p.ParticipantID AS ClientID,
            ClientType = 1, p.LastName + ', ' + p.FirstName + ' ' + p.MI as ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Participants p INNER JOIN Referrals r ON p.ParticipantID =r.ClientID AND r.ClientTypeID = 1
            INNER JOIN Intakes i ON r.IntakeID = i.IntakeID
            INNER 
JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON gt.TargetID = sr.StaffID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON g.GrantID = gt.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID NOT IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND p.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
            UNION ALL
        -- Child referrals to victim service programs by grant-funded staff (935)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 935, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Referrals r ON ci.ChildIntakeID = r.IntakeID AND r.ClientTypeID = 2
            INNER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON sr.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND c.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Child referrals to other services/supports/resource (936)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, c.ChildID + 1000000 AS ClientID,
            ClientType = 1, c.LastName + ', ' + c.FirstName + ' ' + c.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM Children c INNER JOIN ChildIntakes ci ON c.ChildID = ci.ChildID
            INNER JOIN Intakes i ON ci.IntakeID = i.IntakeID
            INNER JOIN Referrals r ON ci.ChildIntakeID = r.IntakeID AND r.ClientTypeID = 2
            INNER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON sr.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
            LEFT OUTER JOIN IntakeVictimType ivt ON i.IntakeID = ivt.IntakeID
        WHERE ivt.VictimTypeID IS NOT NULL AND r.ReferralTypeID NOT IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND i.DeletedDate IS NULL AND c.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Community Member referrals to victim service programs by grant-funded staff (935)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 935, cm.MemberID + 3000000 AS ClientID,
            ClientType = 1, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM CommunityMembers cm INNER JOIN Referrals r ON cm.MemberID = r.ClientID AND r.ClientTypeID = 4 
            INNER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON sr.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE cm.VictimTypeID BETWEEN 3 AND 99 AND r.ReferralTypeID IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND cm.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        UNION ALL
        -- Community Member referrals to other services/supports/resource (936)
        SELECT ByShelter = CAST(0 AS BIT), g.GrantID, g.ContractNumber, g.Prorate, GrantorServiceID = 936, cm.MemberID + 3000000 AS ClientID,
            ClientType = 1, cm.LastName + ', ' + cm.FirstName + ' ' + cm.MI AS ClientName, r.ReferralDate AS EventDate, r.ReferralID AS EventID,
            ServiceUnits = r.NumberReferrals
        FROM CommunityMembers cm INNER JOIN Referrals r ON cm.MemberID = r.ClientID AND r.ClientTypeID = 4 
            INNER JOIN StaffReferrals sr ON r.ReferralID = sr.ReferralID
            INNER JOIN GrantTargets gt ON sr.StaffID = gt.TargetID AND gt.TargetTypeID = 4
            INNER JOIN Grants g ON gt.GrantID = g.GrantID
        WHERE cm.VictimTypeID BETWEEN 3 AND 99 AND r.ReferralTypeID NOT IN (9, 10, 11, 13, 17, 18, 19)
            AND r.ReferralDate BETWEEN @StartDate AND @EndDate
            AND r.DeletedDate IS NULL AND g.DeletedDate IS NULL AND cm.DeletedDate IS NULL
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd AND g.GrantorID = 9
        ORDER BY g.GrantID, ClientID, EventID, ByShelter; 

    -- Unmet requests for services
    -- Evaluated over the entire grant period
        SELECT g.GrantID, g.ContractNumber, x.ReasonDenied, sr.ReasonDeniedID, COUNT(x.ReasonDeniedID) AS NumberDenied
        FROM Calls c INNER JOIN ShelterRequests sr ON c.CallID = sr.CallID
            INNER JOIN xReasonDenied x ON x.ReasonDeniedID = sr.ReasonDeniedID
            INNER JOIN Shelters s ON c.ShelterID = s.ShelterID
            INNER JOIN GrantTargets gt ON s.ShelterID = gt.TargetID AND gt.TargetTypeID = 1
            INNER JOIN Grants g ON g.GrantID = gt.GrantID
        WHERE sr.ReasonDeniedID > 0
            AND g.GrantorID = 9 AND c.CallDate BETWEEN g.GrantStart AND g.GrantEnd
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND c.DeletedDate IS NULL AND g.DeletedDate IS NULL
        GROUP BY g.GrantID, g.ContractNumber, x.ReasonDenied, sr.ReasonDeniedID
        ORDER BY g.GrantID, x.ReasonDenied; 

    -- Number of surveys completed
        SELECT g.GrantID, g.ContractNumber, COUNT(q.QuestionnaireID) AS Questionnaires
        FROM Grants g INNER JOIN GrantSurveys gs ON g.GrantID = gs.GrantID
            INNER JOIN Questionnaires q ON gs.SurveyID = q.SurveyID
        WHERE g.GrantorID = 9 AND q.CompletedDate BETWEEN g.GrantStart AND g.GrantEnd
            AND @StartDate BETWEEN g.GrantStart AND g.GrantEnd
            AND q.DeletedDate IS NULL AND g.DeletedDate IS NULL
        GROUP BY g.GrantID, ContractNumber
        ORDER BY g.GrantID; 

    -- Narratives
        SELECT Item14 =ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '14'), ''),
            Item15 = ISNULL((SELECT TOP 1 Narrative FROM ReportNarratives WHERE ReportNumber = @ReportNumber AND ReportDate = @StartDate AND Item = '15'), '') ; 

    -- Service Map, used to show users in report how their services are mapped to VOCA service types (TableName:  ServiceMap)
        SELECT ISNULL(s.ServiceName, 'UNMAPPED') AS ServiceName, ISNULL(f.Focus, '') AS Focus, gs.GrantorService
        FROM GrantorServices gs LEFT OUTER JOIN ServiceMap sm ON gs.GrantorServiceID = sm.GrantorServiceID
            LEFT OUTER JOIN ServiceFocus sf ON sm.ServiceFocusID = sf.ServiceFocusID
            LEFT OUTER JOIN Services s ON sf.ServiceID = s.ServiceID
            LEFT OUTER JOI
N Focus f ON sf.FocusID = f.FocusID
        WHERE sm.GrantorID = 9 AND s.DiscontinuedDate IS NULL
        UNION ALL
        SELECT s.ServiceName, f.Focus, 'UNMAPPED' AS GrantorService
        FROM ServiceFocus sf INNER JOIN Services s ON sf.ServiceID = s.ServiceID
            INNER JOIN Focus f ON sf.FocusID = f.FocusID
        WHERE sf.ServiceFocusID NOT IN
            (SELECT ServiceFocusID FROM ServiceMap WHERE GrantorID = 9)
            AND s.DiscontinuedDate IS NULL
        ORDER BY ServiceName, Focus;

rpt_VolunteerActivities
CREATE PROCEDURE dbo.rpt_VolunteerActivities
	(@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS       
                SELECT ProvidedService = 0, s.StaffID, LastName + ', ' + FirstName + ' ' + MI AS StaffName, Activity, ActivityDate, va.Hours, Anonymous = CAST(0 AS BIT), Volunteers = 1
                FROM Staff s INNER JOIN VolunteerActivity va ON s.StaffID = va.StaffID
                    INNER JOIN VolunteerActivities vs ON va.ActivityID = vs.ActivityID
                WHERE ActivityDate BETWEEN @StartDate AND @EndDate
                    AND s.DeletedDate IS NULL AND vs.DeletedDate IS NULL 
                UNION ALL 
                SELECT ProvidedService = 1, s.StaffID, LastName + ', ' + FirstName + ' ' + MI AS StaffName, ServiceName, SessionDate, SessionHours, Anonymous = CAST(0 AS BIT), Volunteers = 1
                FROM Staff s INNER JOIN StaffSessions ss ON s.StaffID = ss.StaffID AND s.Status = 2 
                    INNER JOIN [Sessions] sss ON ss.SessionID = sss.SessionID 
                    INNER JOIN Services svc ON sss.ServiceID = svc.ServiceID 
                WHERE SessionDate BETWEEN @StartDate AND @EndDate 
                    AND s.DeletedDate IS NULL AND sss.DeletedDate IS NULL 
                UNION ALL 
                SELECT ProvidedService = 0, StaffID = 0, StaffName = 'Anonymous (' + CONVERT(VARCHAR(4), OneTimeVolunteers) + ')', Activity, ActivityDate, OneTimeVolunteers * OneTimeHours, Anonymous = CAST(1 AS BIT), OneTimeVolunteers 
                FROM VolunteerActivities vs LEFT OUTER JOIN VolunteerActivity va ON vs.ActivityID = va.ActivityID
                WHERE ActivityDate BETWEEN @StartDate AND @EndDate 
                    AND DeletedDate IS NULL
                    AND OneTimeVolunteers > 0
                ORDER BY Anonymous, StaffName, ActivityDate;

rpt_ZipCodesServed
CREATE PROCEDURE rpt_ZipCodesServed
    (@StartDate SMALLDATETIME, @EndDate SMALLDATETIME, @ReportNumber INT)
	AS
    -- Residential Clients
    SELECT s.ShelterName, x.IntakeType, i.IntakeTypeID, s.ShelterID,
         CASE WHEN i.Zip = '' THEN 'Unknown' ELSE LEFT(i.Zip, 5) END AS ZipCode, 
         Children =
        (SELECT COUNT(ChildIntakeID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL)
    FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE i.EntryDate <= @EndDate
        AND(i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
        AND i.IntakeTypeID IN(1, 2, 3, 5)
    UNION ALL
    -- Non - residents who received a service
    SELECT s.ShelterName, x.IntakeType, i.IntakeTypeID, s.ShelterID,
         CASE WHEN i.Zip = '' THEN 'Unknown' ELSE LEFT(i.Zip, 5) END AS ZipCode,
         Children =
        (SELECT COUNT(ChildIntakeID) FROM ChildIntakes WHERE IntakeID = i.IntakeID AND DeletedDate IS NULL)
    FROM Intakes i INNER JOIN Shelters s ON i.ShelterID = s.ShelterID
        INNER JOIN xIntakeType x ON i.IntakeTypeID = x.IntakeTypeID
    WHERE i.EntryDate <= @EndDate
        AND(i.ExitDate IS NULL OR i.ExitDate >= @StartDate)
        AND i.DeletedDate IS NULL
        AND i.IntakeTypeID NOT IN(1, 2, 3, 5)
        AND(SELECT TOP 1 s.SessionID
            FROM Sessions s INNER JOIN ClientSessions cs ON s.SessionID = cs.SessionID
            WHERE cs.ClientID = i.ParticipantID) IS NOT NULL
    ORDER BY s.ShelterName, i.IntakeTypeID, ZipCode;