367 lines
7.2 KiB
Transact-SQL
367 lines
7.2 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[_8DGetAuditReport] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[_8DGetAuditReport] @AuditNo varchar(100) = NULL,
|
|
@AuditTitle varchar(100) = NULL,
|
|
@AuditTypeID int = NULL,
|
|
@AuditorID int = NULL,
|
|
@AuditDateFrom date = NULL,
|
|
@AuditDateTo date = NULL,
|
|
@FindingCategoryID int = NULL,
|
|
@AuditAreaIDs varchar(max) = NULL,
|
|
@HasOpenCA bit = NULL,
|
|
@OpenCAOwner varchar(100) = NULL,
|
|
@HasOpenAI bit = NULL,
|
|
@OpenAIOwner varchar(100) = NULL,
|
|
@AuditStatus int = NULL,
|
|
@MajorMinorFinding varchar(100) = NULL,
|
|
@ViolatedClause varchar(100) = NULL,
|
|
@5SOFIFindings varchar(100) = 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
|
|
@AuditNo AS AuditNo,
|
|
@AuditTitle AS AuditTitle,
|
|
@AuditTypeID AS AuditTypeID,
|
|
@AuditorID AS AuditorID,
|
|
@AuditDateFrom AS AuditDateFrom,
|
|
@AuditDateTo AS AuditDateTo,
|
|
@FindingCategoryID AS FindingCategoryID,
|
|
@AuditAreaIDs AS AuditAreaIDs,
|
|
@HasOpenCA AS HasOpenCA,
|
|
@OpenCAOwner AS OpenCAOwner,
|
|
@HasOpenAI AS HasOpenAI,
|
|
@OpenAIOwner AS OpenAIOwner,
|
|
@AuditStatus AS AuditStatus,
|
|
@MajorMinorFinding AS MajorMinorFinding,
|
|
@ViolatedClause AS ViolatedClause,
|
|
@5SOFIFindings AS [_5SOFIFindings],
|
|
@BaseURL AS BaseURL FOR XML PATH
|
|
)
|
|
SELECT
|
|
dbo.fnAuditConvertAuditNoToDisplayFormat(A.AuditNo) AS AuditNo,
|
|
AuditTitle,
|
|
AT.AuditTypes AS AuditType,
|
|
REPLACE(AA.Auditors, ',', ', ') AS Auditors,
|
|
Auditees,
|
|
A.AuditDate,
|
|
REPLACE(AF.Categories, ',', ', ') AS FindingCategories,
|
|
REPLACE(Area.AuditedAreas, ',', ', ') AS AuditedAreas,
|
|
REPLACE(CAOwners, ',', ', ') AS PendingCAOwners,
|
|
REPLACE(CAFind.PendingAIOwners, ',', ', ') AS PendingCAFindingsAIOwners,
|
|
AuditScore,
|
|
CASE
|
|
WHEN AuditStatus = 0 THEN 'Open'
|
|
WHEN AuditStatus = 1 THEN 'Closed'
|
|
ELSE 'Cancelled'
|
|
END AS AuditStatus,
|
|
(
|
|
SELECT
|
|
COUNT(*)
|
|
FROM
|
|
_8DAuditFinding AF2
|
|
WHERE
|
|
FindingType = 'Major'
|
|
AND AF2.AuditNo = A.AuditNo
|
|
) AS NoOfMajorNonConformities,
|
|
(
|
|
SELECT
|
|
COUNT(*)
|
|
FROM
|
|
_8DAuditFinding AF2
|
|
WHERE
|
|
FindingType = 'Minor'
|
|
AND AF2.AuditNo = A.AuditNo
|
|
) AS NoOfMinorNonConformities,
|
|
(
|
|
SELECT
|
|
'`* ' + LTRIM(RTRIM(CAST(AF2.Findings AS VARCHAR(350))))
|
|
FROM
|
|
_8DAuditFinding AF2
|
|
WHERE
|
|
AF2.AuditNo = A.AuditNo
|
|
ORDER BY
|
|
AssignedDate FOR XML PATH('')
|
|
) AS MajorMinorFindings,
|
|
(
|
|
SELECT
|
|
'`* ' + LTRIM(RTRIM(CAST(AF2.ViolatedClause AS VARCHAR(350))))
|
|
FROM
|
|
_8DAuditFinding AF2
|
|
WHERE
|
|
AF2.AuditNo = A.AuditNo
|
|
ORDER BY
|
|
AssignedDate FOR XML PATH('')
|
|
) AS ViolatedClause,
|
|
(
|
|
SELECT
|
|
'`* ' + LTRIM(
|
|
RTRIM(
|
|
CA.CAType + ' (' + dbo.fn8DConvertCANoToCADisplayFormat(CA.CANo) + ')'
|
|
)
|
|
)
|
|
FROM
|
|
_8DAuditFinding AF2,
|
|
_8DCorrectiveAction CA
|
|
WHERE
|
|
AF2.AuditNo = A.AuditNo
|
|
AND CA.CANo = AF2.CANo
|
|
ORDER BY
|
|
CA.CAType,
|
|
CA.IssueDate FOR XML PATH('')
|
|
) AS [8DStatus],
|
|
(
|
|
SELECT
|
|
'`* ' + F.CAFinding
|
|
FROM
|
|
_8DCAFindings F
|
|
WHERE
|
|
F.AuditNo = A.AuditNo
|
|
ORDER BY
|
|
AssignedDate FOR XML PATH('')
|
|
) AS [5S_OFI_Findings],
|
|
(
|
|
SELECT
|
|
'`* ' + F.CorrectiveAction
|
|
FROM
|
|
_8DCAFindings F
|
|
WHERE
|
|
F.AuditNo = A.AuditNo
|
|
ORDER BY
|
|
AssignedDate FOR XML PATH('')
|
|
) AS [5S_OFI_CorrectiveAction],
|
|
(
|
|
SELECT
|
|
'`* ' + F.Result
|
|
FROM
|
|
_8DCAFindings F
|
|
WHERE
|
|
F.AuditNo = A.AuditNo
|
|
ORDER BY
|
|
AssignedDate FOR XML PATH('')
|
|
) AS [5S_OFI_Result],
|
|
(
|
|
SELECT
|
|
'`* ' + AR.[FileName]
|
|
FROM
|
|
_8DAuditAttachment_Reports AR
|
|
WHERE
|
|
AR.AuditNo = A.AuditNo
|
|
AND CAFindingsID IS NULL
|
|
ORDER BY
|
|
1 FOR XML PATH('')
|
|
) AS [Attachments],
|
|
@BaseURL + '/Audit/Edit?IssueID=' + CONVERT(varchar(20), A.AuditNo) AS [URL]
|
|
FROM
|
|
_8DAudit A
|
|
LEFT JOIN _8DAuditType T ON A.AuditTypeID = T.ID
|
|
LEFT JOIN v8DAuditorsByAudit AA ON A.AuditNo = AA.AuditNo
|
|
LEFT JOIN v8DAuditFindingsByAudit AF ON A.AuditNo = AF.AuditNo
|
|
LEFT JOIN v8DAuditedAreas Area ON A.AuditNo = Area.AuditNo
|
|
LEFT JOIN v8DPendingCAFindingsAIOwners CAFind ON A.AuditNo = CAFind.AuditNo
|
|
LEFT JOIN v8DPendingCAOwners COA ON A.AuditNo = COA.AuditNo
|
|
LEFT JOIN v8DAuditTypesByAudit AT ON A.AuditNo = AT.AuditNo
|
|
WHERE
|
|
(
|
|
@AuditNo IS NULL
|
|
OR dbo.fnAuditConvertAuditNoToDisplayFormat(A.AuditNo) LIKE '%' + @AuditNo + '%'
|
|
)
|
|
AND (
|
|
@AuditTitle IS NULL
|
|
OR ISNULL(A.AuditTitle, '') LIKE '%' + @AuditTitle + '%'
|
|
)
|
|
AND (
|
|
ISNULL(@AuditTypeID, -1) = -1
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditTypeByAudit x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.AuditTypeID = @AuditTypeID
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@AuditorID, -1) = -1
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditorsByAudit x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.AuditorID = @AuditorID
|
|
)
|
|
)
|
|
AND (
|
|
@AuditDateFrom IS NULL
|
|
OR @AuditDateFrom <= CONVERT(date, A.AuditDate)
|
|
)
|
|
AND (
|
|
@AuditDateTo IS NULL
|
|
OR CONVERT(date, A.AuditDate) <= @AuditDateTo
|
|
)
|
|
AND (
|
|
ISNULL(@FindingCategoryID, -1) = -1
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditFinding x,
|
|
_8DAuditFindingCategoryByAuditFinding y
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND y.AuditFindingID = x.ID
|
|
AND y.CategoryID = @FindingCategoryID
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@AuditAreaIDs, '') = ''
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditedAreaByAudit x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.AuditedAreaID IN (
|
|
SELECT
|
|
Val
|
|
FROM
|
|
dbo.fnSplitCSV(@AuditAreaIDs)
|
|
)
|
|
)
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
dbo.fnSplitCSV(@AuditAreaIDs)
|
|
WHERE
|
|
Val = -1
|
|
)
|
|
)
|
|
AND (
|
|
@HasOpenCA IS NULL
|
|
OR (
|
|
@HasOpenCA = 1
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditFinding x,
|
|
_8DCorrectiveAction y
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND y.CANo = x.CANo
|
|
AND y.ClosedDate IS NULL
|
|
)
|
|
)
|
|
OR (
|
|
@HasOpenCA = 0
|
|
AND NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditFinding x,
|
|
_8DCorrectiveAction y
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND y.CANo = x.CANo
|
|
AND y.ClosedDate IS NULL
|
|
)
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@OpenCAOwner, '') = ''
|
|
OR CAOwners LIKE '%' + @OpenCAOwner + '%'
|
|
)
|
|
AND (
|
|
@HasOpenAI IS NULL
|
|
OR (
|
|
@HasOpenAI = 1
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DCAFindings x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.ImplementedDate IS NULL
|
|
)
|
|
)
|
|
OR (
|
|
@HasOpenAI = 0
|
|
AND NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DCAFindings x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.ImplementedDate IS NULL
|
|
)
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@OpenAIOwner, '') = ''
|
|
OR CAFind.PendingAIOwners LIKE '%' + @OpenAIOwner + '%'
|
|
)
|
|
AND (
|
|
ISNULL(@AuditStatus, -1) = -1
|
|
OR AuditStatus = @AuditStatus
|
|
)
|
|
AND (
|
|
ISNULL(@MajorMinorFinding, '') = ''
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditFinding x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.Findings LIKE '%' + @MajorMinorFinding + '%'
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@ViolatedClause, '') = ''
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DAuditFinding x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.ViolatedClause LIKE '%' + @ViolatedClause + '%'
|
|
)
|
|
)
|
|
AND (
|
|
ISNULL(@5SOFIFindings, '') = ''
|
|
OR EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
_8DCAFindings x
|
|
WHERE
|
|
x.AuditNo = A.AuditNo
|
|
AND x.CAFinding LIKE '%' + @5SOFIFindings + '%'
|
|
)
|
|
)
|
|
ORDER BY
|
|
A.AuditNo
|
|
END
|
|
GO |