210 lines
4.8 KiB
Transact-SQL
210 lines
4.8 KiB
Transact-SQL
USE [FabApprovalSystem]
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[ECNGetPdfItem] Script Date: 11/21/2024 11:29:04 AM ******/
|
|
SET
|
|
ANSI_NULLS ON
|
|
GO
|
|
SET
|
|
QUOTED_IDENTIFIER ON
|
|
GO
|
|
CREATE PROCEDURE [dbo].[ECNGetPdfItem] -- Add the parameters for the stored procedure here
|
|
@ECNNumber INT AS BEGIN DECLARE @ParentECNNumber INT;
|
|
|
|
DECLARE @SuperParentECNNumber INT;
|
|
|
|
-- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
--SELECT COUNT(*) FROM dbo.fnIsUserITARCompliant(114)
|
|
-- Insert statements for procedure here
|
|
SELECT
|
|
E.ECNNumber,
|
|
E.Title,
|
|
E.IssueDate,
|
|
E.SubmitedDate,
|
|
E.CloseDate,
|
|
E.OriginatorID,
|
|
E.IsECN,
|
|
E.IsTECN,
|
|
E.IsEmergencyTECN,
|
|
E.ExpirationDate,
|
|
E.ExtensionDate,
|
|
E.CancellationDate,
|
|
E.AcknowledgementRequired,
|
|
E.TrainingRequired,
|
|
E.AreaID,
|
|
E.TechnologyID,
|
|
E.PCRBRequired,
|
|
E.PCRBNumber,
|
|
E.TestProgramChangeRequired,
|
|
E.SPCChangeRequired,
|
|
E.NewPartFlowRequired,
|
|
E.SPNChangeRequired,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.ImplementationDetails),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS ImplementationDetails,
|
|
E.ImpactOnEnvironment,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.ImpactOnEnvironmentDescription),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS ImpactOnEnvironmentDescription,
|
|
E.ImpactOnCapacity,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.ImpactOnCapacityDescription),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS ImpactOnCapacityDescription,
|
|
E.IsMA,
|
|
E.IsRH,
|
|
E.IsAU,
|
|
E.IsIndustrial,
|
|
E.MaterialConsumptionChangeRequired,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.MaterialConsumptionChangeDescription),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS MaterialConsumptionChangeDescription,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.ReasonForChange),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS ReasonForChange,
|
|
REPLACE(
|
|
dbo.EncodeHtml(E.DescriptionOfChange),
|
|
char(10),
|
|
'<BR/>'
|
|
) AS DescriptionOfChange,
|
|
E.NotAFlowChange,
|
|
E.AttachECN_TECNToLots,
|
|
E.SPNFlowChangeAtSingleStep,
|
|
E.SPNFlowChangeAtMultipleSteps,
|
|
E.CurrentStep,
|
|
E.CancellationApprovalDate,
|
|
E.TECNExtensionState,
|
|
U.FirstName + ' ' + LastName AS 'OriginatorName',
|
|
A.Area,
|
|
T.Technology,
|
|
E.ConvertedFromNumber,
|
|
E.ConvertedToNumber,
|
|
E.FIChangeRequired,
|
|
E.NumberOfLotsAffected,
|
|
CASE
|
|
WHEN E.RecipeChange = 1 THEN 'Yes'
|
|
WHEN RecipeChange = 0 THEN 'No'
|
|
ELSE ''
|
|
END AS RecipeChange,
|
|
IsDocEC
|
|
FROM
|
|
ECN E
|
|
INNER JOIN Users U ON E.OriginatorID = U.UserID
|
|
LEFT JOIN ECNArea A ON E.AreaID = A.AreaID
|
|
LEFT JOIN ECNTechnology T ON E.TechnologyID = T.TechnologyID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
SRC.SubRoleCategoryItem AS AffectedDepartments
|
|
FROM
|
|
ECNAffectedDepartment ED
|
|
INNER JOIN SubRoleCategory SRC ON ED.DepartmentID = SRC.SubRoleCategoryID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
M.ModuleName AS AffectedModules
|
|
FROM
|
|
ECNAffectedModule EM
|
|
INNER JOIN ECNModule M ON EM.ModuleID = M.ModuleID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
[FileName] AS Attachments
|
|
FROM
|
|
ECNAttachment
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
@ParentECNNumber = ISNULL(ConvertedFromNumber, -1)
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ECNNumber;
|
|
|
|
IF @ParentECNNumber <> -1 -- If the current document is an ECN and was converted from E-TECN -> TECN -> ECN
|
|
BEGIN
|
|
SELECT
|
|
@SuperParentECNNumber = ISNULL(ConvertedFromNumber, -1)
|
|
FROM
|
|
ECN
|
|
WHERE
|
|
ECNNumber = @ParentECNNumber;
|
|
|
|
END
|
|
SELECT
|
|
U.FirstName + ' ' + U.LastName AS FullName,
|
|
A.OperationType Operation,
|
|
ISNULL(SRC.SubRoleCategoryItem, 'N/A') AS SubRole,
|
|
LogDateTime AS OperationTime
|
|
FROM
|
|
ApprovalLog A
|
|
INNER JOIN Users U ON A.UserID = U.UserID
|
|
LEFT JOIN SubRole SR ON A.SubRoleID = SR.SubRoleID
|
|
LEFT JOIN SubRoleCategory SRC ON SR.SubRoleCategoryID = SRC.SubRoleCategoryID
|
|
WHERE
|
|
(
|
|
OperationType = 'Approved'
|
|
OR OperationType = 'Denied'
|
|
OR OperationType LIKE '%CHANGED%'
|
|
OR OperationType LIKE '%Cancel%'
|
|
OR OperationType LIKE '%Expir%'
|
|
OR OperationType LIKE '%initiated%'
|
|
)
|
|
AND (
|
|
IssueID = @ECNNumber
|
|
OR IssueID = @ParentECNNumber
|
|
OR IssueID = @SuperParentECNNumber
|
|
)
|
|
AND (
|
|
DocumentTypeID = 3
|
|
OR DocumentTypeID = 4
|
|
OR DocumentTypeID = 5
|
|
)
|
|
ORDER By
|
|
LogDateTime DESC
|
|
SELECT
|
|
A.Area AS AffectedAreas
|
|
FROM
|
|
ECNAffectedArea E
|
|
INNER JOIN ECNArea A ON E.AreaID = A.AreaID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
T.Technology AS Afefctedtechologies
|
|
FROM
|
|
ECNAffectedTechnology E
|
|
INNER JOIN ECNTechnology T ON E.TechnologyID = T.TechnologyID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
A.AcknowledgementTrainingBy AS AcknowledgementBy
|
|
FROM
|
|
ECNAcknowledgementBy E
|
|
INNER JOIN ECNAcknowledgementTrainingBy A ON E.AcknowledgementTrainingByID = A.AcknowledgementTrainingByID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
A.AcknowledgementTrainingBy AS TrainingBy
|
|
FROM
|
|
ECNTrainingBy T
|
|
INNER JOIN ECNAcknowledgementTrainingBy A ON T.AcknowledgementTrainingByID = A.AcknowledgementTrainingByID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
SELECT
|
|
PF.ProductFamily AS AffectedProductFamily
|
|
FROM
|
|
ECNAffectedProductFamily E
|
|
INNER JOIN ProductFamilies PF ON E.ProductFamilyID = PF.ProductFamilyID
|
|
WHERE
|
|
ECNNumber = @ECNNumber
|
|
END
|
|
GO |