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

310 lines
6.5 KiB
Transact-SQL

USE [FabApprovalSystem]
GO
/****** Object: StoredProcedure [dbo].[ECNGetReport] Script Date: 11/21/2024 11:29:04 AM ******/
SET
ANSI_NULLS ON
GO
SET
QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[ECNGetReport] @ECNNumber varchar(50) = NULL,
@OriginatorID int = NULL,
@Title varchar(100) = NULL,
@ECNTypes varchar(max) = NULL,
@DepartmentID int = NULL,
@AffectedModuleIDs varchar(max) = NULL,
@PendingApproverID int = NULL,
@SubmitDateFrom date = NULL,
@SubmitDateTo date = NULL,
@CloseDateFrom date = NULL,
@CloseDateTo date = NULL,
@ExpirationDateFrom date = NULL,
@ExpirationDateTo date = NULL,
@ExtensionDateFrom date = NULL,
@ExtensionDateTo 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
@ECNNumber AS ECNNumber,
@OriginatorID AS OriginatorID,
@Title AS Title,
@ECNTypes AS ECNTypes,
@DepartmentID AS DepartmentID,
@AffectedModuleIDs AS AffectedModuleIDs,
@PendingApproverID AS PendingApproverID,
@SubmitDateFrom AS SubmitDateFrom,
@SubmitDateTo AS SubmitDateTo,
@CloseDateFrom AS CloseDateFrom,
@CloseDateTo AS CloseDateTo,
@ExpirationDateFrom AS ExpirationDateFrom,
@ExpirationDateTo AS ExpirationDateTo,
@ExtensionDateFrom AS ExtensionDateFrom,
@ExtensionDateTo AS ExtensionDateTo,
@BaseURL AS BaseURL FOR XML PATH
)
SELECT
E.ECNNumber,
CASE
WHEN E.IsECN = 1 THEN 'ECN'
WHEN E.IsTECN = 1 THEN 'TECN'
WHEN E.IsEmergencyTECN = 1 THEN 'E-TECN'
ELSE 'ECN'
END AS ECNType,
U.FirstName + ' ' + U.LastName AS Originator,
Title,
STUFF(
(
SELECT
', ' + D.SubRoleCategoryItem
FROM
ECNAffectedDepartment
INNER JOIN SubRoleCategory D ON D.SubRoleCategoryID = ECNAffectedDepartment.DepartmentID
AND D.SubRoleCategory = 'Department'
WHERE
ECNAffectedDepartment.ECNNumber = E.ECNNumber FOR XML PATH('')
),
1,
2,
''
) AS [Departments],
STUFF(
(
SELECT
', ' + ECNModule.ModuleName
FROM
ECNAffectedModule
INNER JOIN ECNModule ON ECNModule.ModuleID = ECNAffectedModule.ModuleID
WHERE
ECNAffectedModule.ECNNumber = E.ECNNumber FOR XML PATH('')
),
1,
2,
''
) AS [AffectedModules],
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 IN (3, 4)
AND A.IssueID = E.ECNNumber
AND ItemStatus = 0 FOR XML PATH('')
),
1,
3,
''
) AS [PendingApprovers],
SubmitedDate,
CloseDate,
ExpirationDate,
ExtensionDate,
CancellationDate,
ConvertedFromNumber,
ConvertedToNumber,
STUFF(
(
SELECT
' / ' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50))
FROM
ECNAcknowledgementBy
INNER JOIN Users U ON U.UserID = ECNAcknowledgementBy.AcknowledgementTrainingByID
WHERE
ECNAcknowledgementBy.ECNNumber = E.ECNNumber FOR XML PATH('')
),
1,
3,
''
) AS [AckNotificationTo],
STUFF(
(
SELECT
' / ' + CAST(U.FirstName AS varchar(50)) + ' ' + CAST(U.LastName AS varchar(50))
FROM
ECNTrainingBy
INNER JOIN Users U ON U.UserID = ECNTrainingBy.AcknowledgementTrainingByID
WHERE
ECNTrainingBy.ECNNumber = E.ECNNumber FOR XML PATH('')
),
1,
3,
''
) AS [TrainingNotificationTo],
STUFF(
(
SELECT
', ' + ECNArea.Area
FROM
ECNAffectedArea
INNER JOIN ECNArea ON ECNArea.AreaID = ECNAffectedArea.AreaID
WHERE
ECNAffectedArea.ECNNumber = E.ECNNumber FOR XML PATH(''),
TYPE
).value('.[1]', 'nvarchar(max)'),
1,
2,
''
) AS [AffectedAreas],
STUFF(
(
SELECT
', ' + ECNTechnology.Technology
FROM
ECNAffectedTechnology t
INNER JOIN ECNTechnology ON ECNTechnology.TechnologyID = t.TechnologyID
WHERE
t.ECNNumber = E.ECNNumber FOR XML PATH(''),
TYPE
).value('.[1]', 'nvarchar(max)'),
1,
2,
''
) AS [UnitProcess],
PCRBNumber,
TestProgramChangeRequired,
SPCChangeRequired,
NewPartFlowRequired,
SPNChangeRequired,
ImplementationDetails,
ReasonForChange,
DescriptionOfChange,
(
SELECT
'`* ' + A.FileName
FROM
ECNAttachment A
WHERE
A.ECNNumber = E.ECNNumber
ORDER BY
A.UploadDate FOR XML PATH(''),
TYPE
).value('.[1]', 'nvarchar(max)') AS [AttachmentFilenames],
@BaseURL + '/ECN/Edit?IssueID=' + CONVERT(varchar(10), E.ECNNumber) AS [URL]
FROM
ECN E
LEFT JOIN Users U ON E.OriginatorID = U.UserID
WHERE
E.Deleted = 0
AND (
@ECNNumber IS NULL
OR CONVERT(varchar(50), E.ECNNumber) LIKE '%' + @ECNNumber + '%'
)
AND (
ISNULL(@OriginatorID, -1) = -1
OR E.OriginatorID = @OriginatorID
)
AND (
@Title IS NULL
OR E.Title LIKE '%' + @Title + '%'
)
AND (
@ECNTypes IS NULL
OR CASE
WHEN E.IsECN = 1 THEN 'ECN'
WHEN E.IsTECN = 1 THEN 'TECN'
WHEN E.IsEmergencyTECN = 1 THEN 'E-TECN'
ELSE 'ECN'
END IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@ECNTypes)
)
)
AND (
ISNULL(@DepartmentID, -1) = -1
OR EXISTS (
SELECT
1
FROM
ECNAffectedDepartment D
WHERE
D.ECNNumber = E.ECNNumber
AND D.DepartmentID = @DepartmentID
)
)
AND (
@AffectedModuleIDs IS NULL
OR EXISTS (
SELECT
1
FROM
dbo.fnSplitCSV(@AffectedModuleIDs)
WHERE
Val = -1
)
OR EXISTS (
SELECT
1
FROM
ECNAffectedModule M
WHERE
M.ECNNumber = E.ECNNumber
AND M.ModuleID IN (
SELECT
Val
FROM
dbo.fnSplitCSV(@AffectedModuleIDs)
)
)
)
AND (
ISNULL(@PendingApproverID, -1) = -1
OR EXISTS (
SELECT
1
FROM
Approval A
WHERE
A.DocumentTypeID IN (3, 4)
AND A.IssueID = E.ECNNumber
AND ItemStatus = 0
AND A.UserID = @PendingApproverID
)
)
AND (
@SubmitDateFrom IS NULL
OR @SubmitDateFrom <= CONVERT(date, E.SubmitedDate)
)
AND (
@SubmitDateTo IS NULL
OR CONVERT(date, E.SubmitedDate) <= @SubmitDateTo
)
AND (
@CloseDateFrom IS NULL
OR @CloseDateFrom <= CONVERT(date, E.CloseDate)
)
AND (
@CloseDateTo IS NULL
OR CONVERT(date, E.CloseDate) <= @CloseDateTo
)
AND (
@ExpirationDateFrom IS NULL
OR @ExpirationDateFrom <= CONVERT(date, E.ExpirationDate)
)
AND (
@ExpirationDateTo IS NULL
OR CONVERT(date, E.ExpirationDate) <= @ExpirationDateTo
)
AND (
@ExtensionDateFrom IS NULL
OR @ExtensionDateFrom <= CONVERT(date, E.ExtensionDate)
)
AND (
@ExtensionDateTo IS NULL
OR CONVERT(date, E.ExtensionDate) <= @ExtensionDateTo
)
ORDER BY
E.ECNNumber
END
GO