mesa-fab-approval/Programmability/Stored Procedures/GetOpenActionItemsReport.sql
Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

273 lines
9.9 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[GetOpenActionItemsReport] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[GetOpenActionItemsReport] @IssueNo varchar(50) = NULL,
@DocumentTypes varchar(max) = NULL,
@ResponsiblePeopleIDs varchar(max) = NULL,
@AssignedFrom date = NULL,
@AssignedTo date = NULL,
@DueDateFrom date = NULL,
@DueDateTo date = NULL,
@Username varchar(100) = '',
@BaseURL varchar(100) = NULL AS BEGIN -- 2019/01/28 - add overdue CA (ticket #35315)
SELECT
* INTO #docTypes FROM dbo.fnSplitCSV(@DocumentTypes)
SELECT
* INTO #rpIDs FROM dbo.fnSplitCSV(@ResponsiblePeopleIDs)
IF EXISTS (
SELECT
1
FROM
#rpIDs WHERE Val = -1)
DELETE FROM
#rpIDs
INSERT INTO
ReportLog([ProcName], [Username], [Parms])
SELECT
OBJECT_NAME(@ @PROCID),
@Username,
(
SELECT
@IssueNo AS IssueNo,
@DocumentTypes AS DocumentTypes,
@ResponsiblePeopleIDs AS ResponsiblePeopleIDs,
@AssignedFrom AS AssignedFrom,
@AssignedTo AS AssignedTo,
@DueDateFrom AS DueDateFrom,
@DueDateTo AS DueDateTo,
@BaseURL AS BaseURL FOR XML PATH
)
SELECT
*
FROM
(
SELECT
dbo.fn8DConvertCANoToCADisplayFormat(CNT.CANo) AS [IssueNo],
'Corrective Action' AS [DocumentType],
CA.CATitle AS [Title],
U1.FirstName + ' ' + U1.LastName AS [ResponsiblePeople],
CNT.ContainmentAction AS [ActionItems],
CONVERT(date, CNT.AssignedDate) AS [AssignedDate],
CONVERT(date, ECD) AS [DueDate],
@BaseURL + '/CorrectiveAction/Edit?IssueID=' + CONVERT(varchar(10), CNT.CANo) AS [URL]
FROM
_8D_D3ContainmentAction CNT
INNER JOIN _8DCorrectiveAction CA On CNT.CANo = CA.CANo
LEFT JOIN Users U1 ON CNT.ResponsibilityOwnerID = U1.UserID
WHERE
CNT.ImplementedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs) OR CNT.ResponsibilityOwnerID IN (SELECT Val FROM #rpIDs))
UNION
ALL
SELECT
dbo.fn8DConvertCANoToCADisplayFormat(CNT.CANo),
'Corrective Action',
CA.CATitle AS [Title],
U1.FirstName + ' ' + U1.LastName,
CNT.CorrectiveAction,
CONVERT(date, CNT.AssignedDate),
CONVERT(date, ECD),
@BaseURL + '/CorrectiveAction/Edit?IssueID=' + CONVERT(varchar(10), CNT.CANo)
FROM
_8D_D5D6CorrectiveAction CNT
INNER JOIN _8DCorrectiveAction CA On CNT.CANo = CA.CANo
LEFT JOIN Users U1 ON CNT.ResponsibilityOwnerID = U1.UserID
WHERE
ImplementedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs) OR CNT.ResponsibilityOwnerID IN (SELECT Val FROM #rpIDs))
UNION
ALL
SELECT
dbo.fn8DConvertCANoToCADisplayFormat(CNT.CANo),
'Corrective Action' AS DocumentType,
CA.CATitle AS [Title],
U1.FirstName + ' ' + U1.LastName,
CNT.PreventiveAction,
CONVERT(date, CNT.AssignedDate),
CONVERT(date, ECD),
@BaseURL + '/CorrectiveAction/Edit?IssueID=' + CONVERT(varchar(10), CNT.CANo)
FROM
_8D_D7PreventiveAction CNT
INNER JOIN _8DCorrectiveAction CA On CNT.CANo = CA.CANo
LEFT JOIN Users U1 ON CNT.ResponsibilityOwnerID = U1.UserID
WHERE
ImplementedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs) OR CNT.ResponsibilityOwnerID IN (SELECT Val FROM #rpIDs))
UNION
ALL
SELECT
dbo.fnAuditConvertAuditNoToDisplayFormat(A.AuditNo),
'Audit',
A.AuditTitle,
U1.FirstName + ' ' + U1.LastName,
AF.CorrectiveAction,
CONVERT(date, AF.AssignedDate),
CONVERT(date, ECD),
@BaseURL + '/Audit/Edit?IssueID=' + CONVERT(varchar(10), A.AuditNo)
FROM
_8DCAFindings AF
INNER JOIN _8DAudit A On AF.AuditNo = A.AuditNo
LEFT JOIN Users U1 ON AF.ResponsibilityOwnerID = U1.UserID
WHERE
ImplementedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs) OR AF.ResponsibilityOwnerID IN (SELECT Val FROM #rpIDs))
UNION
ALL
SELECT
dbo.fnPlanConvertPlanNoToDisplayFormat(CC.PlanNumber),
'Change Control',
CC.Title,
STUFF(
(
SELECT
', ' + LTRIM(
RTRIM(
CAST(U.FirstName + ' ' + U.LastName AS VARCHAR(50))
)
)
FROM
CCMeetingActionItemResponsible AIR
INNER JOIN Users U ON AIR.ActionItemResponsible = U.UserID
WHERE
AIR.MeetingActionItemID = AI.ID FOR XML PATH('')
),
1,
2,
''
),
AI.ActionItemName,
CONVERT(date, CM.MeetingDate),
CONVERT(date, AI.DueDate),
@BaseURL + '/ChangeControl/Edit?IssueID=' + CONVERT(varchar(10), CC.PlanNumber)
FROM
CCChangeControl CC
INNER JOIN CCMeeting CM ON CC.PlanNumber = CM.PlanNumber
INNER JOIN CCMeetingActionItem AI ON CM.MeetingID = AI.MeetingID
WHERE
AI.ClosedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs)
OR EXISTS (
SELECT
1
FROM
CCMeetingActionItemResponsible AIR,
#rpIDs WHERE AIR.MeetingActionItemID = AI.ID AND AIR.ActionItemResponsible = #rpIDs.Val))
UNION
ALL
SELECT
CONVERT(varchar(20), M.MRBNumber) AS IssueID,
'MRB',
M.Title,
CASE
WHEN ResponsibilityOwnerID IS NULL THEN ResponsibilityOwner
ELSE U1.FirstName + ' ' + U1.LastName
END,
CA.ContainmentAction,
CONVERT(date, CA.AssignedDate),
CONVERT(date, ECD),
@BaseURL + '/MRB/Edit?IssueID=' + CONVERT(varchar(10), M.MRBNumber)
FROM
MRB M
INNER JOIN MRBContainmentAction CA On M.MRBNumber = CA.MRBNumber
LEFT JOIN Users U1 ON CA.ResponsibilityOwnerID = U1.UserID
WHERE
ImplementedDate IS NULL
AND (
NOT EXISTS (
SELECT
1
FROM
#rpIDs) OR CA.ResponsibilityOwnerID IN (SELECT Val FROM #rpIDs))
UNION
ALL
SELECT
dbo.fn8DConvertCANoToCADisplayFormat(CA.CANo),
'Corrective Action' AS DocumentType,
CA.CATitle AS [Title],
U1.FirstName + ' ' + U1.LastName,
CA.CATitle,
CONVERT(date, CA.IssueDate),
CONVERT(date, CA.D8DueDate),
@BaseURL + '/CorrectiveAction/Edit?IssueID=' + CONVERT(varchar(10), CA.CANo)
FROM
_8DCorrectiveAction CA
LEFT JOIN Users U1 ON CA.D1AssigneeID = U1.UserID
WHERE
CA.CACompleteDate IS NULL
AND CA.D8DueDate <= CONVERT(date, GETDATE())
) AS OpenAI
WHERE
(
ISNULL(@IssueNo, '') = ''
OR CONVERT(varchar(100), [IssueNo]) LIKE '%' + @IssueNo + '%'
)
AND (
NOT EXISTS (
SELECT
1
FROM
#docTypes) OR [DocumentType] IN (SELECT Val FROM #docTypes))
AND (
@AssignedFrom IS NULL
OR (
[AssignedDate] >= @AssignedFrom
AND [AssignedDate] IS NOT NULL
)
)
AND (
@AssignedTo IS NULL
OR (
[AssignedDate] <= @AssignedTo
AND [AssignedDate] IS NOT NULL
)
)
AND (
@DueDateFrom IS NULL
OR (
[DueDate] >= @DueDateFrom
AND [DueDate] IS NOT NULL
)
)
AND (
@DueDateTo IS NULL
OR (
[DueDate] <= @DueDateTo
AND [DueDate] IS NOT NULL
)
)
ORDER BY
OpenAI.[DueDate] ASC,
[IssueNo]
END
GO