72 lines
		
	
	
		
			7.1 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
			
		
		
	
	
			72 lines
		
	
	
		
			7.1 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
USE [VEPROMS]
 | 
						||
GO
 | 
						||
/****** Object:  StoredProcedure [dbo].[addItemChild]    Script Date: 01/20/2010 14:26:48 ******/
 | 
						||
SET ANSI_NULLS ON
 | 
						||
GO
 | 
						||
SET QUOTED_IDENTIFIER ON
 | 
						||
GO
 | 
						||
	
 | 
						||
--http://www.code-magazine.com/articleprint.aspx?quickid=0305111&page=4&printmode=true
 | 
						||
--http://aleemkhan.wordpress.com/2006/07/21/t-sql-error-handling-pattern-for-nested-transactions-and-stored-procedures/
 | 
						||
ALTER PROCEDURE [dbo].[addItemChild]
 | 
						||
(
 | 
						||
	@ItemID int=null,	@Number nvarchar(30)=null,	@Text nvarchar(MAX)=null,	@FormatID int=null,	@Config nvarchar(MAX)=null,
 | 
						||
	@FromType int=null,	@Type int=null,	@DTS datetime,	@UserID nvarchar(100),	@newItemID int output
 | 
						||
)
 | 
						||
WITH EXECUTE AS OWNER
 | 
						||
AS
 | 
						||
BEGIN TRY -- Try Block
 | 
						||
	BEGIN TRANSACTION
 | 
						||
	DECLARE @ChildID int,	@ContentID int,	@ParentContentID int,	@LastChanged timestamp
 | 
						||
	,	@newLastChanged timestamp, @Error int, @Rowcount int
 | 
						||
  SELECT @ChildID = pp.[ItemID],@ParentContentID = ii.ContentID, @LastChanged = pp.LastChanged
 | 
						||
		FROM [ITEMS] ii
 | 
						||
		LEFT JOIN [PARTS] pp on pp.ContentID=ii.ContentID and pp.FromType=@FromType
 | 
						||
		WHERE ii.[ItemID]=@ItemID
 | 
						||
	EXECUTE AddContent @Number, @Text, @Type, @FormatID, @Config, @DTS, @UserID, @ContentID output, @newLastChanged output
 | 
						||
	EXECUTE AddItem null, @ContentID,	@DTS,	@UserID ,	@newItemID output,	@newLastChanged output
 | 
						||
	IF @ChildID is null -- No existing child - Add Parts record
 | 
						||
		EXECUTE AddPart 	@ParentContentID, @FromType, @newItemID, @DTS, @UserID, @newLastChanged output
 | 
						||
	ELSE -- Update existing Parts record
 | 
						||
		BEGIN
 | 
						||
			EXECUTE UpdatePart @ParentContentID, @FromType, @newItemID, @DTS, @UserID, @LastChanged, @newLastChanged output
 | 
						||
			UPDATE [Items] SET [PreviousID]=@newItemID WHERE [ItemID]=@ChildID
 | 
						||
			-- Update content records for the transitions
 | 
						||
			Update CC
 | 
						||
				Set Text = DBO.vefn_FixTransitionText(Text,TT.TransitionID,TT.TranType,TT.ToID,TT.RangeID,@ItemID,@newItemID)
 | 
						||
			From CONTENTS CC
 | 
						||
				JOIN Transitions TT ON TT.FromID = CC.ContentID
 | 
						||
				WHERE TT.ToID = @ChildID OR TT.RangeID = @ChildID
 | 
						||
			-- Update transitions that pointed to @ItemID to point to @newItemID
 | 
						||
			Update TRANSITIONS
 | 
						||
				Set ToID = CASE ToID WHEN @ChildID THEN @newItemID ELSE ToID END,
 | 
						||
					RangeID = CASE RangeID WHEN @ChildID THEN @newItemID ELSE RangeID END
 | 
						||
					WHERE ToID = @ChildID OR RangeID = @ChildID
 | 
						||
			-- Add 'Verification Required' AnnotationType
 | 
						||
			DECLARE @typeID int
 | 
						||
			SELECT @typeID = TypeID from AnnotationTypes where Name = 'Verification Required'
 | 
						||
			IF(@typeID IS NULL)
 | 
						||
			BEGIN
 | 
						||
				INSERT INTO [AnnotationTypes]	([Name],[UserID])	VALUES	('Verification Required','Volian')
 | 
						||
				SELECT @typeID = SCOPE_IDENTITY()
 | 
						||
			END
 | 
						||
			-- Add "Verification Required" Annotation for each Transition that points to @newItemID or @NextID
 | 
						||
			-- I don't expect to see any transitions that point to @ChildID.  They should have changed in
 | 
						||
			-- the update above to point to @newItemID.  This is here for consistency with the other insert
 | 
						||
			-- stored procedures
 | 
						||
			INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID])
 | 
						||
				SELECT ItemID, @typeID,'Verify Transition Destination',@UserID
 | 
						||
				FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS
 | 
						||
				where ToID IN(@ChildID,@newItemID) OR RangeID IN(@ChildID,@newItemID))
 | 
						||
			-- Transition Text gets updated in ItemInsertExt.cs
 | 
						||
		END
 | 
						||
	IF( @@TRANCOUNT > 0 ) COMMIT
 | 
						||
  PRINT 'Child Added ' + ltrim(str(@newItemID))
 | 
						||
	EXECUTE GetItem @newItemID
 | 
						||
END TRY
 | 
						||
BEGIN CATCH -- Catch Block
 | 
						||
	IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level
 | 
						||
 	ELSE IF( @@TRANCOUNT > 1 ) COMMIT -- Otherwise commit.  Top level will rollback
 | 
						||
	EXEC vlnErrorHandler
 | 
						||
END CATCH
 |