Mike Phares ab800974b7 Programmability objects from database
Removed commented code
Added fn_GetExpiredTECNByOriginator
2024-12-12 12:15:46 -07:00

465 lines
8.9 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[_8DGetCAReport] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[_8DGetCAReport] @CANo varchar(50) = NULL,
@CASourceIDs varchar(max) = NULL,
@RequestorID int = NULL,
@AssigneeID int = NULL,
@IssueDateFrom date = NULL,
@IssueDateTo date = NULL,
@CATitle varchar(100) = NULL,
@Status varchar(100) = NULL,
@HasPendingApprover bit = NULL,
@OpenActionItemOwnerIDs varchar(max) = NULL,
@DueDateFrom date = NULL,
@DueDateTo date = NULL,
@CloseDateFrom date = NULL,
@CloseDateTo date = NULL,
@ApprovalDateFrom date = NULL,
@ApprovalDateTo date = NULL,
@Modules varchar(max) = NULL,
@HasTool bit = NULL,
@HasRelatedMRB bit = NULL,
@BaseURL varchar(100) = NULL,
@Username varchar(100) = '' AS BEGIN -- 2019/02/11 fix related audit # field
SET
XACT_ABORT ON
INSERT INTO
ReportLog([ProcName], [Username], [Parms])
SELECT
OBJECT_NAME(@ @PROCID),
@Username,
(
SELECT
@CANo AS CANo,
@CASourceIDs AS CASourceIDs,
@RequestorID AS RequestorID,
@AssigneeID AS AssigneeID,
@IssueDateFrom AS IssueDateFrom,
@IssueDateTo AS IssueDateTo,
@CATitle AS CATitle,
@Status AS [Status],
@HasPendingApprover AS HasPendingApprover,
@OpenActionItemOwnerIDs AS OpenActionItemOwnerIDs,
@DueDateFrom AS DueDateFrom,
@DueDateTo AS DueDateTo,
@CloseDateFrom AS CloseDateFrom,
@CloseDateTo AS CloseDateTo,
@ApprovalDateFrom AS ApprovalDateFrom,
@ApprovalDateTo AS ApprovalDateTo,
@Modules AS Modules,
@HasTool AS HasTool,
@HasRelatedMRB AS HasRelatedMRB,
@BaseURL AS BaseURL FOR XML PATH
)
SELECT
[dbo].[fn8DConvertCANoToCADisplayFormat](CA.CANo) AS CANo,
S.CASource,
U.FirstName + ' ' + U.LastName AS RequestorName,
(
SELECT
TOP 1 FirstName + ' ' + LastName
FROM
Users
WHERE
Users.UserID = CA.D1AssigneeID
) AS D1AssigneeName,
CA.IssueDate,
CA.CATitle,
CASE
WHEN ClosedDate IS NOT NULL THEN 'Closed'
WHEN Status = 0 THEN 'Open'
WHEN Status = 1 THEN 'Closed'
WHEN Status = 2 THEN 'Cancelled'
WHEN Status = 3 THEN 'D3'
WHEN Status = 4 THEN 'D4'
WHEN Status = 5 THEN 'D5'
WHEN Status = 6 THEN 'D6'
WHEN Status = 7 THEN 'D7'
WHEN Status = 8 THEN 'D8'
WHEN Status = 9 THEN 'D1'
WHEN Status = 10 THEN 'D0'
END AS StatusName,
STUFF(
(
SELECT
' / ' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50)) + '(' + A.RoleName + ')'
FROM
Approval A
INNER JOIN Users U ON A.UserID = U.UserID
WHERE
A.DocumentTypeID = 9
AND A.IssueID = CA.CANo
AND ItemStatus = 0
ORDER BY
1 FOR XML PATH('')
),
1,
3,
''
) AS PendingApprovers,
REPLACE(
STUFF(
(
SELECT
', ' + PendingAIOwner
FROM
v8DOpenActionItemOwners AI
WHERE
CA.CANo = AI.IssueID
ORDER BY
1 FOR XML PATH('')
),
1,
2,
''
),
'&',
'&'
) AS PendingAIOwners,
CA.D8DueDate,
ClosedDate,
ApprovedDate,
REPLACE(
STUFF(
(
SELECT
', ' + Module.ModuleName
FROM
_8DCAModuleByCA
INNER JOIN Module ON Module.ModuleID = _8DCAModuleByCA.ModuleID
WHERE
_8DCAModuleByCA.CANo = CA.CANo
ORDER BY
1 FOR XML PATH('')
),
1,
2,
''
),
'&',
'&'
) AS Modules,
(
SELECT
TOP 1 FirstName + ' ' + LastName
FROM
Users
WHERE
Users.UserID = CA.QAID
) AS QAName,
STUFF(
(
SELECT
', ' + FirstName + ' ' + LastName
FROM
_8DCATeamMember
INNER JOIN Users ON Users.UserID = _8DCATeamMember.TeamMemberID
WHERE
_8DCATeamMember.CANo = CA.CANo
ORDER BY
1 FOR XML PATH('')
),
1,
2,
''
) AS TeamMembers,
Tool,
RelatedMRB,
(
SELECT
TOP 1 AuditNo
FROM
_8DAuditFinding af
WHERE
af.CANo = CA.CANo
) AS RelatedAudit,
'Upto ' + CAType AS CAType,
D2ProblemDescription,
(
SELECT
'`* ' + ContainmentAction
FROM
_8D_D3ContainmentAction
WHERE
_8D_D3ContainmentAction.CANo = CA.CANo
ORDER BY
Section,
AssignedDate FOR XML PATH('')
) AS [D2-D4Actions],
STUFF(
(
SELECT
', ' + _8D_D3RiskAssessmentArea.RiskAssessmentArea
FROM
_8DCA_RiskAssessmentAreaByCANo
INNER JOIN _8D_D3RiskAssessmentArea ON _8D_D3RiskAssessmentArea.ID = _8DCA_RiskAssessmentAreaByCANo.RiskAssessmentAreaID
WHERE
_8DCA_RiskAssessmentAreaByCANo.CANo = CA.CANo FOR XML PATH('')
),
1,
2,
''
) AS RiskAssessment,
D3RiskAssessmentNotes,
CASE
WHEN ISNULL(D4RootCause1, '') <> '' THEN '`* '
ELSE ''
END + ISNULL(D4RootCause1, '') + CASE
WHEN ISNULL(D4RootCause2, '') <> '' THEN '`* '
ELSE ''
END + ISNULL(D4RootCause2, '') + CASE
WHEN ISNULL(D4RootCause3, '') <> '' THEN '`* '
ELSE ''
END + ISNULL(D4RootCause3, '') + CASE
WHEN ISNULL(D4RootCause4, '') <> '' THEN '`* '
ELSE ''
END + ISNULL(D4RootCause4, '') AS D4RootCauses,
(
SELECT
'`* ' + CorrectiveAction
FROM
_8D_D5D6CorrectiveAction
WHERE
_8D_D5D6CorrectiveAction.CANo = CA.CANo
ORDER BY
AssignedDate FOR XML PATH('')
) AS [D5-D6CorrectiveActions],
(
SELECT
'`* ' + PreventiveAction
FROM
_8D_D7PreventiveAction
WHERE
_8D_D7PreventiveAction.CANo = CA.CANo
ORDER BY
AssignedDate FOR XML PATH('')
) AS D7PreventativeActions,
(
SELECT
'`* ' + [FileName]
FROM
_8DCAAttachment
WHERE
_8DCAAttachment.CANo = CA.CANo
ORDER BY
_8DCAAttachment.Section,
_8DCAAttachment.UploadDateTime FOR XML PATH('')
) AS Attachments,
@BaseURL + '/CorrectiveAction/Edit?IssueID=' + CONVERT(varchar(10), CA.CANo) AS [URL]
FROM
_8DCorrectiveAction CA
LEFT JOIN Users U ON CA.RequestorID = U.UserID
LEFT JOIN _8DCASource S ON CA.CASourceID = S.ID
WHERE
(
ISNULL(@CANo, '') = ''
OR [dbo].[fn8DConvertCANoToCADisplayFormat](CA.CANo) LIKE '%' + @CANo + '%'
)
AND (
ISNULL(@CASourceIDs, '') = ''
OR CA.CASourceID IN (
SELECT
val
FROM
dbo.fnSplitCSV(@CASourceIDs)
)
)
AND (
ISNULL(@RequestorID, -1) = -1
OR CA.RequestorID = @RequestorID
)
AND (
ISNULL(@AssigneeID, -1) = -1
OR CA.D1AssigneeID = @AssigneeID
)
AND (
@IssueDateFrom IS NULL
OR @IssueDateFrom <= CONVERT(date, CA.IssueDate)
)
AND (
@IssueDateTo IS NULL
OR CONVERT(date, CA.IssueDate) <= @IssueDateTo
)
AND (
ISNULL(@CATitle, '') = ''
OR CA.CATitle LIKE '%' + @CATitle + '%'
)
AND (
ISNULL(@Status, '') = ''
OR CASE
WHEN CA.ClosedDate IS NOT NULL THEN 1
ELSE [Status]
END IN (
SELECT
val
FROM
dbo.fnSplitCSV(@Status)
)
)
AND (
@HasPendingApprover IS NULL
OR (
@HasPendingApprover = 1
AND EXISTS (
SELECT
1
FROM
Approval A
WHERE
A.DocumentTypeID = 9
AND A.IssueID = CA.CANo
AND ItemStatus = 0
)
)
OR (
@HasPendingApprover = 0
AND NOT EXISTS (
SELECT
1
FROM
Approval A
WHERE
A.DocumentTypeID = 9
AND A.IssueID = CA.CANo
AND ItemStatus = 0
)
)
)
AND (
ISNULL(@OpenActionItemOwnerIDs, '') = ''
OR EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@OpenActionItemOwnerIDs)
WHERE
Val = -1
)
OR EXISTS (
SELECT
1
FROM
(
SELECT
ResponsibilityOwnerID
FROM
_8D_D3ContainmentAction x
WHERE
x.CANo = CA.CANo
AND x.ImplementedDate IS NULL
UNION
ALL
SELECT
ResponsibilityOwnerID
FROM
_8D_D5D6CorrectiveAction x
WHERE
x.CANo = CA.CANo
AND x.ImplementedDate IS NULL
UNION
ALL
SELECT
ResponsibilityOwnerID
FROM
_8D_D7PreventiveAction x
WHERE
x.CANo = CA.CANo
AND x.ImplementedDate IS NULL
) Y
WHERE
Y.ResponsibilityOwnerID IN (
SELECT
val
FROM
dbo.fnSplitCSV(@OpenActionItemOwnerIDs)
)
)
)
AND (
@DueDateFrom IS NULL
OR @DueDateFrom <= CONVERT(date, CA.D8DueDate)
)
AND (
@DueDateTo IS NULL
OR CONVERT(date, CA.D8DueDate) <= @DueDateTo
)
AND (
@CloseDateFrom IS NULL
OR @CloseDateFrom <= CONVERT(date, CA.ClosedDate)
)
AND (
@CloseDateTo IS NULL
OR CONVERT(date, CA.ClosedDate) <= @CloseDateTo
)
AND (
@ApprovalDateFrom IS NULL
OR @ApprovalDateFrom <= CONVERT(date, CA.ApprovedDate)
)
AND (
@ApprovalDateTo IS NULL
OR CONVERT(date, CA.ApprovedDate) <= @ApprovalDateTo
)
AND (
ISNULL(@Modules, '') = ''
OR EXISTS (
SELECT
1
FROM
_8DCAModuleByCA x,
dbo.fnSplitCSV(@Modules) m
WHERE
x.CANo = CA.CANo
AND x.ModuleID = m.Val
)
OR (
NOT EXISTS (
SELECT
1
FROM
_8DCAModuleByCA x
WHERE
x.CANo = CA.CANo
)
AND EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@Modules)
WHERE
Val = -1
)
)
)
AND (
@HasTool IS NULL
OR (
@HasTool = 1
AND ISNULL(Tool, '') <> ''
)
OR (
@HasTool = 0
AND ISNULL(Tool, '') = ''
)
)
AND (
@HasRelatedMRB IS NULL
OR (
@HasRelatedMRB = 1
AND ISNULL(CA.RelatedMRB, '') NOT IN ('', 'N/A', 'NA')
)
OR (
@HasRelatedMRB = 0
AND ISNULL(CA.RelatedMRB, '') IN ('', 'N/A', 'NA')
)
)
ORDER BY
CA.CANo
END
GO