USE [FabApprovalSystem] GO /****** Object: StoredProcedure [dbo].[MRBInsertSPNMRBHoldFlagReport] Script Date: 11/21/2024 11:29:05 AM ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE PROCEDURE [dbo].[MRBInsertSPNMRBHoldFlagReport] @MRBNumber INT, @MRBHoldFlagReportAttrTable dbo.udtMRBHoldFlagReportTable READONLY AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; DECLARE @ErrorMessage NVARCHAR(4000); DECLARE @ErrorSeverity INT; DECLARE @ErrorState INT; -- Insert statements for procedure here BEGIN TRY BEGIN TRAN INSERT INTO MRBHoldFlagReportHistory ( MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime --,HistoryInsertDateTimeStamp ) SELECT MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime --,GETDATE() FROM @MRBHoldFlagReportAttrTable IF NOT EXISTS ( SELECT 1 FROM MRBHoldFlagReport WHERE MRBNumber = @MRBNumber ) BEGIN INSERT INTO MRBHoldFlagReport ( MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime ) SELECT MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime FROM @MRBHoldFlagReportAttrTable END ELSE BEGIN -- TODO record into the history table before updating -- update the data columns which need to be recorded in the Data Columns that has "Prior" in the name of the field UPDATE MRBHoldFlagReport SET PriorMRB_DispoType = CurrentMRB_DispoType, PriorMRBHoldLocation = CurrentMRBHoldLocation, PriorMRBHoldOperation = CurrentMRBHoldOperation WHERE MRBNumber = @MRBNumber UPDATE M SET CurrentMRB_DispoType = '', CurrentMRBHoldLocation = '', CurrentMRBHoldOperation = '' FROM MRBHoldFlagReport M INNER JOIN @MRBHoldFlagReportAttrTable T ON M.MRBNumber = T.MRBNumber AND M.LotNo = T.LotNo UPDATE M SET M.TransactionType = T.TransactionType, M.PartNo = T.PartNo, M.CurrentLocation = T.CurrentLocation, M.CurrentOperation = T.CurrentOperation, M.StartQty = T.StartQty, M.CurrentQty = T.CurrentQty, M.LotStatus = T.LotStatus, M.OperStatus = T.OperStatus, M.Successful = T.Successful, M.Comment = T.Comment, M.CurrentMRB_DispoType = T.CurrentMRB_DispoType, M.CurrentMRBHoldLocation = T.CurrentMRBHoldLocation, M.CurrentMRBHoldOperation = T.CurrentMRBHoldOperation, M.TransactionDatetime = T.TransactionDatetime FROM MRBHoldFlagReport M INNER JOIN @MRBHoldFlagReportAttrTable T ON M.MRBNumber = T.MRBNumber AND M.LotNo = T.LotNo -- NEW Lots that were added to this MRB in the new Report (Child Split Lots) INSERT INTO MRBHoldFlagReport ( MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime ) SELECT MRBNumber, LotNo, TransactionType, PartNo, CurrentLocation, CurrentOperation, StartQty, CurrentQty, LotStatus, OperStatus, Successful, Comment, PriorMRB_DispoType, PriorMRBHoldLocation, PriorMRBHoldOperation, CurrentMRB_DispoType, CurrentMRBHoldLocation, CurrentMRBHoldOperation, TransactionDatetime FROM @MRBHoldFlagReportAttrTable T WHERE NOT EXISTS ( SELECT 1, 2 FROM MRBHoldFlagReport M WHERE M.MRBNumber = T.MRBNumber AND M.LotNo = T.LotNo ) END COMMIT TRAN END TRY BEGIN CATCH ROLLBACK SELECT @ErrorMessage = ERROR_MESSAGE() + CONVERT(VARCHAR(10), @MRBNumber), @ErrorSeverity = ERROR_SEVERITY(), @ErrorState = ERROR_STATE(); RAISERROR ( @ErrorMessage, -- Message text. @ErrorSeverity, -- Severity. @ErrorState -- State. ); END CATCH END GO