USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[CCGetReport] Script Date: 11/21/2024 11:29:04 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[CCGetReport] @PlanNumber varchar(50) = NULL, @OwnerID int = NULL, @Title varchar(100) = NULL, @ChangeLevel int = NULL, @PCRValue varchar(50) = NULL, @GenerationIDs varchar(max) = NULL, @Tool varchar(100) = NULL, @ProcessIDs varchar(max) = NULL, @StartDateFrom date = NULL, @StartDateTo date = NULL, @ClosedDateFrom date = NULL, @ClosedDateTo date = NULL, @LatestMeetingDateFrom date = NULL, @LatestMeetingDateTo date = NULL, @BaseURL varchar(100) = NULL, @Username varchar(100) = '' AS BEGIN SET XACT_ABORT ON INSERT INTO ReportLog([ProcName], [Username], [Parms]) SELECT OBJECT_NAME(@ @PROCID), @Username, ( SELECT @PlanNumber AS PlanNumber, @OwnerID AS OwnerID, @Title AS Title, @ChangeLevel AS ChangeLevel, @PCRValue AS PCRValue, @GenerationIDs AS GenerationIDs, @Tool AS Tool, @ProcessIDs AS ProcessIDs, @StartDateFrom AS StartDateFrom, @StartDateTo AS StartDateTo, @ClosedDateFrom AS ClosedDateFrom, @ClosedDateTo AS ClosedDateTo, @LatestMeetingDateFrom AS LatestMeetingDateFrom, @LatestMeetingDateTo AS LatestMeetingDateTo, @BaseURL AS BaseURL FOR XML PATH ) SELECT dbo.fnPlanConvertPlanNoToDisplayFormat(C.PlanNumber) AS PlanNumber, Dates.StartDate, U.FirstName + ' ' + U.LastName AS [Owner], C.Title, CASE WHEN ChangeLevel = -1 THEN NULL ELSE ChangeLevel END AS ChangeLevel, CASE WHEN [STATUS] = 1 THEN 'Closed' WHEN [STATUS] = 2 THEN 'Cancelled' WHEN [STATUS] = 0 THEN STUFF( ( SELECT ', ' + LTRIM(RTRIM(CAST(PCRValue AS VARCHAR(50)))) FROM CCMeetingPCRValue P WHERE P.MeetingID = LatestMeeting.MeetingID ORDER BY 1 FOR XML PATH('') ), 1, 2, '' ) ELSE '' END AS PCRBStatus, LatestMeeting.MeetingDate AS LatestMeetingDate, CASE WHEN LatestMeeting.Decision = 1 THEN 'Approved' WHEN LatestMeeting.Decision = 0 THEN 'Not-Approved' ELSE 'Open' END AS LatestMeetingDecision, LatestMeeting.DecisionNotes AS LatestMeetingDecisionNotes, STUFF( ( SELECT ', ' + LTRIM(RTRIM(CAST(Generation AS VARCHAR(50)))) FROM CCGeneration CCG LEFT JOIN CCGenerationMaster GM ON CCG.GenerationID = GM.GenerationID WHERE CCG.PlanNumber = C.PlanNumber FOR XML PATH('') ), 1, 2, '' ) AS Generations, C.ToolTypes, STUFF( ( SELECT ', ' + LTRIM(RTRIM(CAST(Process AS VARCHAR(50)))) FROM CCProcess CCP LEFT JOIN CCProcessMaster PM ON CCP.ProcessID = PM.ProcessID WHERE CCP.PlanNumber = C.PlanNumber FOR XML PATH('') ), 1, 2, '' ) AS Processes, C.ChangeDescription, C.ReasonForChange, ClosedDate, @BaseURL + '/ChangeControl/Edit?IssueID=' + CONVERT(varchar(10), C.PlanNumber) AS [URL] FROM CCChangeControl C LEFT JOIN Users U ON C.OwnerID = U.UserID OUTER APPLY ( SELECT MIN(MeetingDate) AS StartDate, MAX(MeetingDate) AS StatusDate FROM CCMeeting WHERE CCMeeting.PlanNumber = C.PlanNumber GROUP BY PlanNumber ) AS Dates OUTER APPLY ( SELECT TOP 1 CCMeeting.*, CCDecisionSummary.DecisionNotes FROM CCMeeting LEFT OUTER JOIN CCDecisionSummary ON CCDecisionSummary.MeetingID = CCMeeting.MeetingID WHERE CCMeeting.PlanNumber = C.PlanNumber ORDER BY MeetingDate DESC ) AS LatestMeeting WHERE ( @PlanNumber IS NULL OR dbo.fnPlanConvertPlanNoToDisplayFormat(C.PlanNumber) LIKE '%' + @PlanNumber + '%' ) AND ( ISNULL(@OwnerID, -1) = -1 OR C.OwnerID = @OwnerID ) AND ( ISNULL(@Title, '') = '' OR C.Title LIKE '%' + @Title + '%' ) AND ( ISNULL(@ChangeLevel, -1) = -1 OR C.ChangeLevel = @ChangeLevel ) AND ( ISNULL(@PCRValue, '') = '' OR ( @PCRValue = 'Closed' AND [Status] = 1 ) OR ( @PCRValue = 'Cancelled' AND [Status] = 2 ) OR ( [Status] = 0 AND EXISTS ( SELECT 1 FROM CCMeetingPCRValue P WHERE P.MeetingID = LatestMeeting.MeetingID AND P.PCRValue = @PCRValue ) ) ) AND ( ISNULL(@GenerationIDs, '') = '' OR EXISTS ( SELECT 1 FROM CCGeneration CCG WHERE CCG.PlanNumber = C.PlanNumber AND CCG.GenerationID IN ( SELECT Val FROM dbo.fnSplitCSV(@GenerationIDs) ) ) ) AND ( ISNULL(@Tool, '') = '' OR C.ToolTypes LIKE '%' + @Tool + '%' ) AND ( ISNULL(@ProcessIDs, '') = '' OR EXISTS ( SELECT 1 FROM CCProcess CCP WHERE CCP.PlanNumber = C.PlanNumber AND CCP.ProcessID IN ( SELECT Val FROM dbo.fnSplitCSV(@ProcessIDs) ) ) ) AND ( @StartDateFrom IS NULL OR @StartDateFrom <= CONVERT(date, Dates.StartDate) ) AND ( @StartDateTo IS NULL OR CONVERT(date, Dates.StartDate) <= @StartDateTo ) AND ( @ClosedDateFrom IS NULL OR @ClosedDateFrom <= CONVERT(date, ClosedDate) ) AND ( @ClosedDateTo IS NULL OR CONVERT(date, ClosedDate) <= @ClosedDateTo ) AND ( @LatestMeetingDateFrom IS NULL OR @LatestMeetingDateFrom <= CONVERT(date, LatestMeeting.MeetingDate) ) AND ( @LatestMeetingDateTo IS NULL OR CONVERT(date, LatestMeeting.MeetingDate) <= @LatestMeetingDateTo ) ORDER BY C.PlanNumber END GO