
Added menu options to correct funtions and procedures Removed Applicability from PurgeData Bug Fixes for Paste/Replace etc. Update DTS and User ID before saving Config Search from current rather than root node
599 lines
23 KiB
Transact-SQL
599 lines
23 KiB
Transact-SQL
/****** Object: StoredProcedure [dbo].[PasteItemReplace] Script Date: 03/20/2012 16:02:54 ******/
|
|
/*
|
|
declare @NewItemID int
|
|
declare @dts datetime
|
|
set @newitemid = 0
|
|
set @dts = getdate()
|
|
exec PasteItemReplace 398,397,20014,@dts,'bodine',@NewItemID output
|
|
*/
|
|
-- ItemID is item to replace
|
|
-- StartItemID is item to copy
|
|
ALTER PROCEDURE [dbo].[PasteItemReplace]
|
|
(
|
|
@ItemID int=null, @StartItemID 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 @ContentID AS INT
|
|
DECLARE @NextItemID AS INT
|
|
DECLARE @PreviousItemID AS INT
|
|
DECLARE @ExternalChildCount AS INT
|
|
DECLARE @ExternalCount AS INT
|
|
DECLARE @Path AS VARCHAR(MAX)
|
|
DECLARE @Children AS TABLE
|
|
(
|
|
ItemID INT PRIMARY KEY,
|
|
ContentID INT
|
|
)
|
|
|
|
-- First check if the replaced item can be deleted, i.e. it doesn't have transitions
|
|
-- pointing to it or children.
|
|
|
|
DECLARE @ExternalTrans TABLE
|
|
(
|
|
[FromItemID] int,
|
|
[TransitionID] [int] NOT NULL,
|
|
[FromID] [int] NOT NULL,
|
|
[ToID] [int] NOT NULL,
|
|
[RangeID] [int] NOT NULL,
|
|
[Config] [nvarchar](max) NULL
|
|
)
|
|
SET NOCOUNT ON
|
|
DECLARE @DeleteID int
|
|
INSERT INTO DeleteLog (UserID) VALUES (@UserID)
|
|
SELECT @DeleteID = SCOPE_IDENTITY()
|
|
SELECT @ContentID = ContentID, @PreviousItemID = PreviousID FROM Items WHERE ItemID = @ItemID
|
|
SELECT @NextItemID = ItemID FROM Items WHERE PreviousID = @ItemID
|
|
--SELECT @ExternalCount = count(*) FROM vefn_FindExternalTransitions(@ItemID)
|
|
SELECT @ExternalChildCount = count(*) FROM vefn_FindExternalChildTransitions(@ItemID)
|
|
SET @Path = [dbo].[ve_GetShortPath](@ItemID)
|
|
|
|
--IF @ExternalCount > 0 AND @NextItemID is null
|
|
--BEGIN
|
|
-- RAISERROR ('###Cannot Delete Item###Step %d has External Transitions and has no next step - (%s)',16,1,@ItemID,@Path)
|
|
-- RETURN
|
|
--END
|
|
|
|
IF @ExternalChildCount > 0
|
|
BEGIN
|
|
RAISERROR ('###Cannot Delete Item###Step %d has External Transitions to it''s children - (%s)',16,1,@ItemID,@Path)
|
|
RETURN
|
|
END
|
|
|
|
-- Copy the item, 'NewItemID' represents the new item(s)
|
|
-- DestFormatID is the formatid for the destination parent's format
|
|
DECLARE @DestFormatID int
|
|
SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0)
|
|
EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT
|
|
|
|
-- Adjust the next/previous to point to the new item
|
|
|
|
DECLARE @PreviousID int
|
|
SELECT @PreviousID = [PreviousID]
|
|
FROM [ITEMS] II
|
|
WHERE [ItemID]=@ItemID
|
|
UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID
|
|
UPDATE [CONTENTS] SET [Type]=@Type
|
|
FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID]
|
|
WHERE [ItemID]=@NewItemID
|
|
UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [PreviousID]=@ItemID
|
|
UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID
|
|
|
|
-- UPDATE DocVersion if this was a procedure
|
|
UPDATE DocVersions SET ItemID=@NewItemID where ItemID = @ItemID
|
|
|
|
-- If there were 'external transitions' that pointed to the original
|
|
-- top replaced step, adjust them to point to the new top.
|
|
INSERT INTO @ExternalTrans SELECT * FROM vefn_FindExternalTransitions(@ItemID)
|
|
IF (SELECT COUNT(*) from @ExternalTrans) > 0
|
|
BEGIN
|
|
-- 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 TransitionID in(Select TransitionID from @ExternalTrans)
|
|
-- Update transitions that point to @ItemID to Point to @NextItemID
|
|
UPDATE TRANSITIONS
|
|
SET ToID = case when ToID = @ItemID then @NewItemID else ToID END,
|
|
RangeID = case when RangeID = @ItemID then @NewItemID else RangeID END
|
|
WHERE TransitionID in(Select TransitionID from @ExternalTrans)
|
|
|
|
DECLARE @typeID int -- AnnotationType
|
|
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' annotions for transtions that pointed to top step
|
|
-- and need to point to
|
|
INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID])
|
|
SELECT ItemID, @typeID,'Verify Replaced Step Transition Destination',@UserID
|
|
FROM Items where ItemID in (SELECT FromItemID FROM @ExternalTrans)
|
|
|
|
END
|
|
-- Remove the old one
|
|
|
|
-- Get list of Children
|
|
INSERT INTO @Children SELECT * FROM vefn_ChildItems(@ItemID)
|
|
-- Delete Annotations for @ItemID and children
|
|
DELETE from Annotations where ItemID in(Select ItemID from @Children)
|
|
-- Delete Details associated with @ContentID and children
|
|
DELETE from Details where ContentID in(Select ContentID from @Children)
|
|
-- Delete Grids associated with @ContentID and children
|
|
DELETE from Grids where ContentID in(Select ContentID from @Children)
|
|
-- Delete Images associated with @ContentID and children
|
|
DELETE from Images where ContentID in(Select ContentID from @Children)
|
|
-- Delete Entries associated with @ContentID and children
|
|
DELETE from Entries where ContentID in(Select ContentID from @Children)
|
|
-- Delete ROUsages associated with @ContentID and children
|
|
DELETE from RoUsages where ContentID in(Select ContentID from @Children)
|
|
-- Delete ZTransitions records associated with @ContentID and children
|
|
DELETE FROM ZTransitions where TransitionID
|
|
in(SELECT TransitionID from Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID)
|
|
-- Delete Transitions associated with @ContentID and children
|
|
DELETE FROM Transitions where FromID in(SELECT ContentID FROM @Children) or FromID = @ContentID
|
|
-- Delete Parts associated with @ContentID and children
|
|
DELETE from Parts where ContentID in(Select ContentID from @Children)
|
|
-- Delete ZContents associated with @ContentID and children
|
|
DELETE from ZContents where ContentID in(Select ContentID from @Children)
|
|
-- Disconnect Items from Each Other
|
|
DELETE from Items where ItemID in(Select ItemID from @Children) and PreviousID Is Not Null
|
|
-- Disconnect Items to be deleted from each other
|
|
Update Items set PreviousID = null where ItemID in (Select ItemID from @Children) and PreviousID Is Not Null
|
|
-- Delete Item Records
|
|
DELETE from Items where ItemID in(Select ItemID from @Children)
|
|
-- DELETE Contents
|
|
DELETE from Contents where ContentID in(Select ContentID from @Children)
|
|
--delete from itemaudits where itemid = @newitemid
|
|
delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid))
|
|
--delete from contentaudits where contentid = (select contentid from items where itemid = @newitemid)
|
|
delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid))
|
|
DELETE from DeleteLog where DeleteID = @DeleteID
|
|
IF( @@TRANCOUNT > 0 ) COMMIT
|
|
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
|
|
|
|
/****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 03/20/2012 17:50:44 ******/
|
|
GO
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
/*
|
|
select * from vefn_chronologyreport(2) where type > 0 order by contentid,auditid
|
|
*/
|
|
/****** Object: UserDefinedFunction [dbo].[vefn_ChronologyReport] Script Date: 05/18/2011 11:20:48 ******/
|
|
ALTER function [dbo].[vefn_ChronologyReport](@ProcItemID int)
|
|
returns @Report table
|
|
(
|
|
src int,
|
|
AuditID bigint,
|
|
ContentID int,
|
|
Number nvarchar(512),
|
|
Text nvarchar(max),
|
|
Type int,
|
|
FormatID int,
|
|
Config nvarchar(max),
|
|
DTS datetime,
|
|
UserID nvarchar(200),
|
|
DeleteStatus int,
|
|
ActionDTS datetime,
|
|
ItemDTS datetime,
|
|
LastAuditID int,
|
|
DeletedAuditID int
|
|
)
|
|
WITH EXECUTE AS OWNER
|
|
AS
|
|
BEGIN
|
|
--added jcb 20111122
|
|
declare @dts datetime
|
|
set @dts = (select dts from items where itemid = @ProcItemID )
|
|
--set @dts = (SELECT .[dbo].[vefn_GetPreviousRevisionDTSByItemID] (@ProcItemID))
|
|
--end added jcb 20111122
|
|
insert into @Report
|
|
SELECT
|
|
1 src,
|
|
[AuditID]
|
|
,ca.[ContentID]
|
|
,[Number]
|
|
,[Text]
|
|
,[Type]
|
|
,[FormatID]
|
|
,[Config]
|
|
,ca.[DTS] cadts
|
|
,ca.[UserID]
|
|
,ca.[DeleteStatus]
|
|
,ActionDTS
|
|
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
|
FROM ContentAudits ca
|
|
-- inner join tblitems ti on ca.contentid = ti.contentid
|
|
where Number is not null
|
|
--added jcb 20111028_1827
|
|
and ca.contentid != (select contentid from items where itemid = @procitemid)
|
|
--end added jcb 20111028_1827
|
|
--added jcb 20111122
|
|
--and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
|
and ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > @dts)
|
|
--and ca.dts > (select dts from items where itemid = @ProcItemID )
|
|
and ca.dts > @dts
|
|
--end added jcb 20111122
|
|
-- UNION
|
|
-- SELECT
|
|
--2 src,
|
|
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
|
---- (select max(auditid) + 1 from contentaudits) [AuditID]
|
|
---- 0 [AuditID]
|
|
-- ,ca.[ContentID]
|
|
-- ,[Number]
|
|
-- ,[Text]
|
|
-- ,[Type]
|
|
-- ,[FormatID]
|
|
-- ,[Config]
|
|
-- ,ca.[DTS] cadts
|
|
-- ,ca.[UserID]
|
|
-- ,ca.[DeleteStatus]
|
|
-- ,ActionDTS
|
|
-- ,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
|
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
|
--,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
|
-- FROM tblContents ca
|
|
---- inner join tblitems ti on ca.contentid = ti.contentid
|
|
--WHERE ca.DeleteStatus = 0 AND
|
|
----added jcb 20111028_1827
|
|
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
|
----end added jcb 20111028_1827
|
|
----ca.ContentID in (SELECT [ContentID] FROM ContentAudits where dts > (select dts from items where itemid = @ProcItemID ))
|
|
----added jcb 20111122
|
|
----ca.ContentID in (SELECT [ContentID] FROM Contents where dts > (select dts from items where itemid = @ProcItemID ))
|
|
--ca.ContentID in (SELECT [ContentID] FROM Contents where dts > @dts)
|
|
----end added jcb 20111122
|
|
----order by ca.DTS,ActionDTS
|
|
UNION
|
|
SELECT
|
|
3 src,
|
|
cast(ident_current('contentaudits') + 1 as bigint) auditid
|
|
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
|
-- 0 [AuditID]
|
|
,ca.[ContentID]
|
|
,[Number]
|
|
,[Text]
|
|
,[Type]
|
|
,[FormatID]
|
|
,[Config]
|
|
,ca.[DTS] cadts
|
|
,ca.[UserID]
|
|
,ca.[DeleteStatus]
|
|
,ActionDTS
|
|
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
|
FROM tblContents ca
|
|
-- inner join tblitems ti on ca.contentid = ti.contentid
|
|
WHERE ca.DeleteStatus = 0 AND
|
|
--added jcb 20111028_1827
|
|
ca.contentid != (select contentid from items where itemid = @procitemid) and
|
|
--end added jcb 20111028_1827
|
|
--added jcb 20111122
|
|
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
|
(ca.dts > @dts or ca.actiondts > @dts)
|
|
--end added jcb 20111122
|
|
UNION
|
|
SELECT distinct
|
|
5 src,
|
|
-- cast(ident_current('contentaudits') + 1 as bigint) auditid
|
|
-- (select max(auditid) + 1 from contentaudits) [AuditID]
|
|
ca.[AuditID]
|
|
,ca.[ContentID]
|
|
,[Number]
|
|
,[Text]
|
|
,[Type]
|
|
,[FormatID]
|
|
,[Config]
|
|
,ca.[DTS] cadts
|
|
,ca.[UserID]
|
|
,ca.[DeleteStatus]
|
|
,ActionDTS
|
|
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null) LastAuditID
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
|
FROM ContentAudits ca
|
|
-- inner join tblitems ti on ca.contentid = ti.contentid
|
|
WHERE ca.DeleteStatus > 0 AND
|
|
--added jcb 20111028_1827
|
|
--ca.contentid != (select contentid from items where itemid = @procitemid) and
|
|
--end added jcb 20111028_1827
|
|
--added jcb 20111122
|
|
--ca.dts > (select dts from items where itemid = @ProcItemID )
|
|
(ca.dts > @dts or ca.actiondts > @dts)
|
|
--end added jcb 20111122
|
|
order by ca.DTS,ActionDTS
|
|
|
|
insert into @Report
|
|
SELECT
|
|
4 src,
|
|
ca.[AuditID]
|
|
,ca.[ContentID]
|
|
,ca.[Number]
|
|
,ca.[Text]
|
|
,ca.[Type]
|
|
,ca.[FormatID]
|
|
,ca.[Config]
|
|
,ca.[DTS] cadts
|
|
,ca.[UserID]
|
|
,ca.[DeleteStatus]
|
|
,ca.ActionDTS
|
|
,(select min(dts) from itemaudits where contentid = ca.contentid) ItemDTS
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null) LastAuditID
|
|
,(select max(auditid) from contentaudits where ca.contentid = contentid and ca.auditid > auditid and number is not null and deletestatus > 0 and ca.dts = dts) DeletedAuditID
|
|
FROM ContentAudits ca
|
|
-- inner join tblitems ti on ca.contentid = ti.contentid
|
|
inner join @Report rpt on ca.contentid = rpt.contentid and ca.auditid = rpt.lastauditid
|
|
where ca.auditid not in (select auditid from @report)
|
|
and rpt.lastauditid is not null
|
|
return
|
|
end
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[PasteItemSiblingAfter] Script Date: 03/21/2012 15:25:31 ******/
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
ALTER PROCEDURE [dbo].[PasteItemSiblingAfter]
|
|
(
|
|
@ItemID int=null, @StartItemID int=null, -- ItemID is destination, StartItemID is top of copy
|
|
@Type int=null, @DTS datetime, @UserID nvarchar(100),
|
|
@NewItemID int output
|
|
)
|
|
WITH EXECUTE AS OWNER
|
|
AS
|
|
BEGIN TRY -- Try Block
|
|
BEGIN TRANSACTION
|
|
-- First make a copy of the input StartItemID
|
|
-- DestFormatID is the formatid for the destination parent's format
|
|
DECLARE @DestFormatID int
|
|
SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0)
|
|
EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT
|
|
-- Adjust previous field
|
|
DECLARE @NextID int
|
|
SELECT @NextID = [ItemID]
|
|
FROM [ITEMS]
|
|
WHERE [PreviousID]=@ItemID
|
|
IF @NextID is not null -- step after the copy point. Adjust it's previous to point to the new step
|
|
BEGIN
|
|
UPDATE [ITEMS] SET [PreviousID]=@NewItemID, [DTS]=@DTS, [UserID]=@UserID where [ItemID]=@NextID
|
|
END
|
|
UPDATE [ITEMS] SET [PreviousID]=@ItemID where [ItemID]=@NewItemID
|
|
UPDATE [CONTENTS] SET [Type]=@Type
|
|
FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID]
|
|
WHERE [ItemID]=@NewItemID
|
|
|
|
|
|
-- Check for Transitions that point to the Next Step
|
|
BEGIN
|
|
-- Get a list of Transitions which need to change children of @ItemID that point to @NextID
|
|
DECLARE @NextStepTransitions TABLE
|
|
(
|
|
[TransitionID] int PRIMARY KEY,
|
|
[FromID] [int],
|
|
[ToID] [int],
|
|
[RangeID] [int],
|
|
[TranType] [int],
|
|
[Config] [nvarchar](max)
|
|
)
|
|
Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@NextID,@ItemID)
|
|
IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions
|
|
BEGIN
|
|
-- Update all transitions in the list to point to @newItemID
|
|
Update TT
|
|
Set TT.ToID = CASE TT.ToID WHEN @NextID THEN @NewItemID ELSE TT.ToID END,
|
|
TT.RangeID = CASE TT.RangeID WHEN @NextID THEN @NewItemID ELSE TT.RangeID END
|
|
From TRANSITIONS TT
|
|
JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID
|
|
-- Update content records for the transitions
|
|
Update CC
|
|
Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@NextID,@NewItemID)
|
|
From CONTENTS CC
|
|
JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID
|
|
END
|
|
END
|
|
-- 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
|
|
INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID])
|
|
SELECT ItemID, @typeID,'Verify Next Step Transition Destination',@UserID
|
|
FROM Items where CONTENTID in (SELECT FromID FROM TRANSITIONS
|
|
where ToID IN(@newItemID) OR RangeID IN(@newItemID))
|
|
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(@NextID) OR RangeID IN(@NextID))
|
|
-- Transition Text gets updated in ItemInsertExt.cs
|
|
|
|
delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid))
|
|
delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid))
|
|
IF( @@TRANCOUNT > 0 ) COMMIT
|
|
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
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[PasteItemSiblingBefore] Script Date: 03/21/2012 15:26:23 ******/
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
ALTER PROCEDURE [dbo].[PasteItemSiblingBefore]
|
|
(
|
|
@ItemID int=null, @StartItemID int=null,
|
|
@Type int=null, @DTS datetime, @UserID nvarchar(100),
|
|
@NewItemID int output
|
|
)
|
|
WITH EXECUTE AS OWNER
|
|
AS
|
|
BEGIN TRY -- Try Block
|
|
BEGIN TRANSACTION
|
|
-- First make a copy of the input CopyStartID
|
|
-- DestFormatID is the formatid for the destination parent's format
|
|
DECLARE @DestFormatID int
|
|
SET @DestFormatID = .dbo.vefn_GetInheritedFormat(@ItemID, 0)
|
|
EXECUTE CopyItemAndChildren @StartItemID, @DestFormatID, @UserID, @NewItemID OUTPUT
|
|
-- First adjust previous fields, may also have to do parts, if before first one in list.
|
|
DECLARE @PreviousID int, @ContentID int, @newLastChanged timestamp, @NewType int
|
|
SELECT @PreviousID = [PreviousID], @NewType=ISNULL(@Type,[Type])
|
|
FROM [ITEMS] II
|
|
JOIN [CONTENTS] CC ON CC.[ContentID]=II.[CONTENTID]
|
|
WHERE [ItemID]=@ItemID
|
|
UPDATE [ITEMS] SET [PreviousID]=@NewItemID where [ItemID]=@ItemID
|
|
UPDATE [ITEMS] SET [PreviousID]=@PreviousID where [ItemID]=@NewItemID
|
|
UPDATE [CONTENTS] SET [Type]=@Type
|
|
FROM [CONTENTS] CC JOIN [ITEMS] ii ON CC.[ContentID]=II.[ContentID]
|
|
WHERE [ItemID]=@NewItemID
|
|
UPDATE [PARTS] SET [ItemID]=@NewItemID where [ItemID]=@ItemID
|
|
UPDATE [DOCVERSIONS] SET [ItemID] = @NewItemID where [ItemID]=@ItemID
|
|
|
|
IF @PreviousID is null -- The step is replacing the first step
|
|
BEGIN
|
|
-- 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 = @ItemID OR TT.RangeID = @ItemID
|
|
-- Update transitions that pointed to @ItemID to point to @newItemID
|
|
Update TRANSITIONS
|
|
Set ToID = CASE ToID WHEN @ItemID THEN @NewItemID ELSE ToID END,
|
|
RangeID = CASE RangeID WHEN @ItemID THEN @NewItemID ELSE RangeID END
|
|
WHERE ToID = @ItemID OR RangeID = @ItemID
|
|
END
|
|
ELSE -- Check for Transitions that point to the Next Step
|
|
BEGIN
|
|
-- Get a list of Transitions which need to change children of @ItemID that point to @NextID
|
|
DECLARE @NextStepTransitions TABLE
|
|
(
|
|
[TransitionID] int PRIMARY KEY,
|
|
[FromID] [int],
|
|
[ToID] [int],
|
|
[RangeID] [int],
|
|
[TranType] [int],
|
|
[Config] [nvarchar](max)
|
|
)
|
|
Insert into @NextStepTransitions select * from vefn_NextStepTransitions(@ItemID,@PreviousID)
|
|
IF (SELECT COUNT(*) from @NextStepTransitions) > 0 -- Next Step Transitions
|
|
BEGIN
|
|
-- Update all transitions in the list to point to @newItemID
|
|
Update TT
|
|
Set TT.ToID = CASE TT.ToID WHEN @ItemID THEN @NewItemID ELSE TT.ToID END,
|
|
TT.RangeID = CASE TT.RangeID WHEN @ItemID THEN @NewItemID ELSE TT.RangeID END
|
|
From TRANSITIONS TT
|
|
JOIN @NextStepTransitions NS ON NS.TransitionID = TT.TransitionID
|
|
-- Update content records for the transitions
|
|
Update CC
|
|
Set Text = DBO.vefn_FixTransitionText(Text,NS.TransitionID,NS.TranType,NS.ToID,NS.RangeID,@ItemID,@NewItemID)
|
|
From CONTENTS CC
|
|
JOIN @NextStepTransitions NS ON NS.FromID = CC.ContentID
|
|
END
|
|
END
|
|
-- 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
|
|
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(@ItemID,@NewItemID) OR RangeID IN(@ItemID,@NewItemID))
|
|
-- Transition Text gets updated in ItemInsertExt.cs
|
|
delete from itemaudits where itemid in (select itemid from vefn_ChildItems(@newitemid))
|
|
delete from contentaudits where contentid in (select contentid from vefn_ChildItems(@newitemid))
|
|
IF( @@TRANCOUNT > 0 ) COMMIT
|
|
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
|
|
GO
|
|
/****** Object: StoredProcedure [dbo].[getContentAuditsChronologyByItemID] Script Date: 03/21/2012 15:58:26 ******/
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
/****** Object: StoredProcedure [getContentAuditsChronologyByItemID] ******/
|
|
/*
|
|
getContentAuditsChronologyByItemID 10154,10154,0
|
|
getContentAuditsChronologyByItemID 42,42,0
|
|
getContentAuditsChronologyByItemID 9,9,0
|
|
getContentAuditsChronologyByItemID 146,146,1
|
|
*/
|
|
ALTER PROCEDURE [dbo].[getContentAuditsChronologyByItemID]
|
|
(
|
|
@ProcedureItemID int,
|
|
@SelectedItemID int,
|
|
@IncludeDeletedChildren int
|
|
)
|
|
|
|
WITH EXECUTE AS OWNER
|
|
AS
|
|
begin
|
|
select distinct [AuditID],[ContentID],[Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID],[DeleteStatus],[ActionDTS],[ActionWhat],[ActionWhen],[Path],ItemID,TypeName,ordinalpath
|
|
from
|
|
(
|
|
select
|
|
case
|
|
when lastauditid is null then 'Added'
|
|
when r.deletestatus > 0 then 'Deleted'
|
|
when lastauditid = -1 then 'Changed'
|
|
when DeletedAuditID is not null then 'Restored'
|
|
-- when DeletedAuditID is not null and lastauditid = deletedauditid then 'Restored'
|
|
else 'Changed'
|
|
end actionwhat
|
|
,actiondts actionwhen
|
|
-- ,case
|
|
-- when lastauditid is null then dts
|
|
-- when r.deletestatus > 0 then ActionDTS
|
|
-- when lastauditid = -1 then dts
|
|
-- when DeletedAuditID is not null then ActionDTS
|
|
-- else dts
|
|
-- end actionwhen
|
|
,(select dbo.vefn_GetStepTypeNameByItemIDandTypeID(t.itemid,r.type)) TypeName
|
|
,*
|
|
from vefn_tblchilditems (@ProcedureItemID,@SelectedItemID,@IncludeDeletedChildren) t
|
|
inner join vefn_chronologyreport(@ProcedureItemID) r
|
|
on t.icontentid = r.contentid
|
|
-- where ActionDTS > procdts or dts > procdts
|
|
) ah
|
|
order by OrdinalPath, contentid,auditid--actionwhen
|
|
RETURN
|
|
end
|