186 lines
4.1 KiB
Transact-SQL
186 lines
4.1 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[CCGetChangeControlList] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
-- =============================================
|
|
-- Author: <Author,,Name>
|
|
-- Create date: <Create Date,,>
|
|
-- Description: <Description,,>
|
|
-- =============================================
|
|
CREATE PROCEDURE [dbo].[CCGetChangeControlList] -- Add the parameters for the stored procedure here
|
|
@UserID INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET
|
|
NOCOUNT ON;
|
|
|
|
-- UNLOCK all the CC records if there are any pending locks
|
|
UPDATE
|
|
CCChangeControl
|
|
SEt
|
|
RecordLocked = 0,
|
|
RecordLockedBy = NULL,
|
|
RecordLockedDate = NULL,
|
|
RecordLockIndicator = 0
|
|
WHERE
|
|
RecordLockedBy = @UserID
|
|
UPDATE
|
|
CCMeeting
|
|
SEt
|
|
RecordLockedBy = NULL,
|
|
RecordLockedDate = NULL,
|
|
RecordLockIndicator = 0
|
|
WHERE
|
|
RecordLockedBy = @UserID -- Insert statements for procedure here
|
|
SELECT
|
|
DISTINCT C.PlanNumber AS IssueID,
|
|
C.Title,
|
|
U.FirstName + ' ' + U.LastName AS Owner,
|
|
C.MesaPlanNo AS MesaIdTitle,
|
|
CASE
|
|
WHEN ChangeLevel = -1 THEN NULL
|
|
ELSE ChangeLevel
|
|
END AS ChangeLevel,
|
|
Dates.StartDate,
|
|
CASE
|
|
WHEN [STATUS] = 1
|
|
OR [STATUS] = 2 THEN ClosedDate
|
|
ELSE Dates.StatusDate
|
|
END AS StatusDate,
|
|
CPCRB.PCRBStatus,
|
|
CCGens.Generations,
|
|
CCLogs.Logistics,
|
|
CCProcess.Processes,
|
|
C.ToolTypes,
|
|
CASE
|
|
WHEN [STATUS] = 1
|
|
OR [STATUS] = 2 THEN ''
|
|
ELSE MAI1.Responsibles
|
|
END AS ActionItemResponsibility
|
|
FROM
|
|
CCChangeControl C
|
|
LEFT JOIN CCMeeting M ON C.PlanNumber = M.PlanNumber
|
|
LEFT JOIN Users U ON C.OwnerID = U.UserID
|
|
LEFT JOIN (
|
|
SELECT
|
|
PlanNumber,
|
|
MIN(MeetingDate) AS StartDate,
|
|
MAX(MeetingDate) AS StatusDate
|
|
FROM
|
|
CCMeeting
|
|
GROUP BY
|
|
PlanNumber
|
|
) AS Dates ON C.PlanNumber = Dates.PlanNumber -- Get Status
|
|
LEFT JOIN (
|
|
SELECT
|
|
PlanNumber,
|
|
CASE
|
|
WHEN [STATUS] = 1 THEN 'Closed'
|
|
WHEN [STATUS] = 2 THEN 'Cancelled'
|
|
WHEN [STATUS] = 0 THEN (
|
|
SELECT
|
|
PCRValues
|
|
FROM
|
|
vCCMeetingPCRs P
|
|
WHERE
|
|
MeetingDate = (
|
|
SELECT
|
|
MAX(MeetingDate)
|
|
FROM
|
|
CCMeeting
|
|
WHERE
|
|
PlanNumber = C.PlanNumber
|
|
)
|
|
AND P.PlanNumber = C.PlanNumber
|
|
)
|
|
ELSE ''
|
|
END AS PCRBStatus
|
|
FROM
|
|
CCChangeControl C
|
|
) AS CPCRB ON C.PlanNumber = CPCRB.PlanNumber -- Concatenate Gens
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT CC.PlanNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
', ' + LTRIM(RTRIM(CAST(Generation AS VARCHAR(50))))
|
|
FROM
|
|
CCGeneration CCG
|
|
LEFT JOIN CCGenerationMaster GM ON CCG.GenerationID = GM.GenerationID
|
|
WHERE
|
|
CCG.PlanNumber = CC.PlanNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Generations
|
|
FROM
|
|
CCChangeControl CC
|
|
) AS CCGens ON C.PlanNumber = CCGens.PlanNumber
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT CC.PlanNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
', ' + LTRIM(RTRIM(CAST(Logistics AS VARCHAR(50))))
|
|
FROM
|
|
CCLogistics CCL
|
|
LEFT JOIN CCLogisticsMaster LM ON CCL.LogisticsID = LM.LogisticsID
|
|
WHERE
|
|
CCL.PlanNumber = CC.PlanNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Logistics
|
|
FROM
|
|
CCChangeControl CC
|
|
) AS CCLogs ON C.PlanNumber = CCLogs.PlanNumber -- Concatenate process
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT CC.PlanNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
', ' + LTRIM(RTRIM(CAST(Process AS VARCHAR(50))))
|
|
FROM
|
|
CCProcess CCP
|
|
LEFT JOIN CCProcessMaster PM ON CCP.ProcessID = PM.ProcessID
|
|
WHERE
|
|
CCP.PlanNumber = CC.PlanNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Processes
|
|
FROM
|
|
CCChangeControl CC
|
|
) AS CCProcess ON C.PlanNumber = CCProcess.PlanNumber --Contcatenate Responsible person
|
|
LEFT JOIN (
|
|
SELECT
|
|
DISTINCT CC.PlanNumber,
|
|
STUFF (
|
|
(
|
|
SELECT
|
|
DISTINCT ', ' + LTRIM(RTRIM(CAST(AIR.Responsibles AS VARCHAR(350))))
|
|
FROM
|
|
CCMeeting CM
|
|
LEFT JOIN dbo.fn_GetMeetingAI_Responsibles_ByCC() AIR ON CM.MeetingID = AIR.MeetingID
|
|
WHERE
|
|
CM.PlanNumber = CC.PlanNumber FOR XML PATH('')
|
|
),
|
|
1,
|
|
1,
|
|
''
|
|
) AS Responsibles
|
|
FROM
|
|
CCChangeControl CC
|
|
) AS MAI1 ON C.PlanNumber = MAI1.PlanNumber
|
|
END
|
|
GO |