B2024-037: Bug fix for copy/replace functionality on procedures and steps. #349

Merged
jjenko merged 4 commits from B2024-037 into Development 2024-07-11 10:54:10 -04:00
Showing only changes of commit fd26f16776 - Show all commits

View File

@ -22226,6 +22226,416 @@ Go
IF (@@Error = 0) PRINT 'Procedure Creation: [vesp_ListUnlinkedItems] Succeeded'
ELSE PRINT 'Procedure Creation: [vesp_ListUnlinkedItems] Error on Creation'
GO
/*
==========================================================================================================
Begin: C2024-004: KL - Update Copy Replace functionality, (remove ''copy of'')
==========================================================================================================
*/
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[CopyItemAndChildren]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
DROP PROCEDURE [CopyItemAndChildren];
GO
/*****************************************************************************
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
Copyright 2024 - Volian Enterprises, Inc. All rights reserved.
*****************************************************************************/
/*
==========================================================================================================
Author: Kevin Laskey
Modified Date: 07/09/2024
Description: Copy Item and its Children
==========================================================================================================
*/
CREATE PROCEDURE [dbo].[CopyItemAndChildren]
(
@StartItemID INT,
@DestFormatID INT,
@UserID NVARCHAR(100),
@NewStartItemID int output
)
WITH EXECUTE AS OWNER
AS
BEGIN TRY -- Try Block
--+-----------------------------------------------------------------+
--& BEGIN TRANSACTION to make these changes temporary &
--+-----------------------------------------------------------------+
BEGIN TRANSACTION
if exists (select * from tblitems where itemid = @StartItemID and DeleteStatus !=0)
BEGIN
RAISERROR ('###Cannot Paste Step###This step has been deleted',16,1)
RETURN
END
DECLARE @Children AS TABLE
(
ItemID INT PRIMARY KEY,
NewItemID INT,
ContentID INT,
NewContentID INT,
FormatID INT,
NewFormatID INT
)
DECLARE @NewDocuments AS TABLE
(
DocID INT PRIMARY KEY,
NewDocID INT
)
-- Locals
DECLARE @DTS DATETIME -- DTS of all New Items
DECLARE @StartContentID INT
Select @StartContentID = ContentID from Items where ItemID = @StartItemID
SET @DTS = GETDATE() -- Get the current Date and Time
-- Get a list of all of the Items to be copied based upon StartItemID and EndItemID
-- If the StartItemID = EndItemID then it is a single item and it's children
INSERT INTO @Children SELECT ItemID,ItemID,ContentID,ContentID,FormatID,FormatID FROM vefn_ChildItemsRange(@StartItemID,@StartItemID,null)
-- <<< Copy Contents >>>
-- Create new content rows to match the existing rows. Set the type to the Current ContentID temporarily
-- so that the new content rows can be associated with the existing content rows.
-- Rem 'Copy Of ' + before first [Number] for C2024-004 (KL)
INSERT INTO Contents
([Number],[Text],[Type],[FormatID],[Config],[DTS],[UserID])
select CASE when [ContentID] = @StartContentID and [Type]<20000 then [Number] else [Number] end,
[Text],[ContentID],[FormatID],[Config],@DTS,@UserID
from Contents where ContentID in(Select ContentID from @Children)
-- Update the @Children with the NewConentIDs
--print 'A ' + cast(datediff(s,@dts,getdate()) as varchar(100))
UPDATE NN set NN.NewContentID = CC.ContentID
From Contents CC
Join @Children NN on NN.ContentID = CC.Type AND CC.DTS = @DTS and CC.UserID = @UserID
-- Reset the Type column in the Contents table with the Type column from the original Records.
--print 'B ' + cast(datediff(s,@dts,getdate()) as varchar(100))
DECLARE @SourceType INT
Select @SourceType = Type from Contents where ContentID = @StartContentID
if @SourceType = 0
BEGIN
UPDATE CC set CC.Type = CC2.Type, CC.DTS = CC2.DTS, CC.UserID = CC2.UserID
From Contents CC
Join @Children NN on NN.NewContentID = CC.ContentID
Join Contents CC2 on NN.ContentID = CC2.ContentID
END
else
BEGIN
UPDATE CC set CC.Type = CC2.Type
From Contents CC
Join @Children NN on NN.NewContentID = CC.ContentID
Join Contents CC2 on NN.ContentID = CC2.ContentID
END
--print 'B1 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Contents are done
-- SELECT * From Contents where DTS = @DTS and UserID = @UserID
-- <<< Copy Grids >>>
INSERT INTO [Grids]([ContentID],[Data],[Config],[DTS],[UserID])
SELECT NN.[NewContentID],[Data],[Config],@DTS,@UserID
FROM [Grids] GG Join @Children NN on GG.ContentID = NN.ContentID
-- <<< Copy Images >>>
--print 'B2 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
INSERT INTO [Images]([ContentID],[ImageType],[FileName],[Data],[Config],[DTS],[UserID])
SELECT NN.[NewContentID],[ImageType],[FileName],[Data],[Config],@DTS,@UserID
FROM [Images] II Join @Children NN on II.ContentID = NN.ContentID
-- Create new item rows based upon the current item rows and the @Children table, with the NewContentIDs
--print 'B3 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
INSERT INTO [Items] ([PreviousID],[ContentID],[DTS],[UserID])
SELECT II.[PreviousID], -- Leave the PreviousID as is for now
NN.NewContentID, @DTS, @UserID
from @Children NN
join Items II on II.ContentID = NN.ContentID
-- Update the @Children with the NewItemIDs
--print 'B4 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
UPDATE NN set NN.NewItemID = II.ItemID
From Items II
Join @Children NN on NN.NewContentID = II.ContentID AND II.DTS = @DTS and II.UserID = @UserID
DECLARE @NewItemID int
SELECT @NewItemID = NewItemID
FROM @Children
WHERE ItemID = @StartItemID
--print 'B5 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
UPDATE NN SET NN.[NewFormatID] = CC.[FormatID]
FROM @Children NN
Join vefn_ChildItemsRange(@NewItemID,@NewItemID,@DestFormatID) CC
ON NN.NewItemID = CC.ItemID
-- The @Children table is now complete
--SELECT * From @Children
-- Update the PreviousID in the new Item rows, to the new ItemIDs based upon the old ItemIDs
--print 'B6 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
Update II Set II.[PreviousID] = NN.NewItemID
from Items II
Join @Children NN on NN.ItemID = II.PreviousID AND II.DTS = @DTS and II.UserID = @UserID
-- Get the new ItemIDs based upon the old ItemIDs
SELECT @NewStartItemID = NewItemID from @Children where ItemID = @StartItemID
--SELECT @NewEndItemID = NewItemID from @Children where ItemID = @EndItemID
-- Set the PreviousID for the starting Item to null temporarily.
-- This will be adjusted based upon where the step is inserted.
--print 'B7 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
Update Items Set PreviousID = null where ItemID = @NewStartItemID
if @SourceType = 0
BEGIN
UPDATE II SET II.DTS = II2.DTS, II.UserID = II2.UserID
From Items II
Join @Children NN on NN.NewItemID = II.ItemID
Join Items II2 on NN.ItemID = II2.ItemID
WHERE NN.ItemID = @StartItemID
END
--print 'C ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Items are done
--SELECT * From Items where DTS = @DTS and UserID = @UserID
-- <<< Copy Parts >>>
INSERT INTO [Parts] ([ContentID],[FromType],[ItemID],[DTS],[UserID])
Select NNF.NewContentID,[FromType],NNT.NewItemID, @DTS, @UserID from Parts PP
JOIN @Children NNF on PP.ContentID = NNF.ContentID
JOIN @Children NNT on PP.ItemID = NNT.ItemID
--print 'D ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Parts are done
-- SELECT * From Parts where DTS = @DTS and UserID = @UserID
-- <<< Copy Annotations >>>
INSERT INTO [Annotations] ([ItemID],[TypeID],[RtfText],[SearchText],[Config],[DTS],[UserID])
Select NewItemID, TypeID, RtfText, SearchText, Config, @DTS, @UserID
from Annotations AA Join @Children NN on AA.ItemID = NN.ItemID
--print 'E ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Annotations are done
-- SELECT * From Annotations where DTS = @DTS and UserID = @UserID
-- <<< Copy Documents and Entries>>>
-- logic to create Entries for Library Documents
INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID])
SELECT NN.[NewContentID],EE.[DocID],@DTS,@UserID
FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') <> ''
-- Logic to create new documents for any documents used that do not have libtitles
INSERT INTO [Documents] ([LibTitle],[DocContent],[DocAscii],[Config],[DTS],[UserID],[FileExtension])
OUTPUT CAST(INSERTED.[LibTitle] as INT),INSERTED.[DocID] INTO @NewDocuments
SELECT str(DD.[DocID]),[DocContent],[DocAscii],[Config],@DTS,@UserID,[FileExtension]
FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
JOIN [Documents] DD on EE.[DocID] = DD.[DocID] and Isnull(LibTitle,'') = ''
UPDATE DD SET LibTitle = ''
FROM Documents DD JOIN @NewDocuments ND on DD.[DocID] = ND.[NewDocID]
where DTS = @DTS and UserID = @UserID
--print 'F ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Documents are Done
-- SELECT * From Documents where DTS = @DTS and UserID = @UserID
-- Logic to create entries for these newly created documents
INSERT INTO [Entries] ([ContentID],[DocID],[DTS],[UserID])
SELECT NN.[NewContentID],ND.[NewDocID],@DTS,@UserID
FROM [Entries] EE JOIN @Children NN on NN.ContentID = EE.ContentID
JOIN @NewDocuments ND on EE.[DocID] = ND.[DocID]
-- Logic to Create DROUsages for these newly created documents
INSERT INTO [DROUsages] ([DocID],[ROID],[Config],[DTS],[UserID],[RODbID])
SELECT ND.[NewDocID],[ROID],[Config],@DTS,@UserID,[RODbID]
FROM [DROUsages] RR
JOIN @NewDocuments ND on RR.[DocID] = ND.[DocID]
--print 'G ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Entries are done
-- SELECT * From Entries EE JOIN Documents DD on ee.DocID = DD.DocID where EE.DTS = @DTS and EE.UserID = @UserID
-- <<< Copy RoUsages >>>
INSERT INTO [RoUsages] ([ContentID],[ROID],[Config],[DTS],[UserID],[RODbID])
SELECT NN.[NewContentID],CAST([ROUsageID] as nvarchar(16)),[Config],@DTS,@UserID,[RODbID]
FROM [RoUsages] RR Join @Children NN on RR.ContentID = NN.ContentID
-- Update content records for newly copied records to use correct RO usage ids in the RO tags
DECLARE @RowsAffected int
SET @RowsAffected=1
WHILE @RowsAffected > 0
BEGIN
UPDATE CC SET [TEXT] = C2.NewText
FROM CONTENTS CC
JOIN (SELECT C1.ContentID, .dbo.vefn_FixROText(C1.Text, CAST([ROID] as int), [ROUsageID]) NewText
FROM CONTENTS C1
JOIN @Children NN on C1.ContentID = NN.NewContentID
JOIN RoUsages RO on NN.NewContentID = RO.ContentID where Len([ROID]) < 12) C2 ON CC.ContentID = C2.ContentID
WHERE [TEXT] <> C2.NewText
SET @RowsAffected = @@RowCount
END
-- Update grid records for newly copied records to use correct RO usage ids in the RO tags
SET @RowsAffected=1
WHILE @RowsAffected > 0
BEGIN
UPDATE GG SET [Data] = G2.NewData
FROM GRIDS GG
JOIN (SELECT G1.ContentID, .dbo.vefn_FixROData(G1.Data, CAST([ROID] as int), [ROUsageID]) NewData
FROM GRIDS G1
JOIN @Children NN on G1.ContentID = NN.NewContentID
JOIN RoUsages RO on NN.NewContentID = RO.ContentID where Len([ROID]) < 12) G2 ON GG.ContentID = G2.ContentID
WHERE Cast([Data] as nvarchar(max)) <> cast(G2.NewData as nvarchar(max))
SET @RowsAffected = @@RowCount
END
UPDATE RON SET [ROID] = ROO.[ROID]
FROM RoUsages RON
JOIN @Children NN on RON.ContentID = NN.NewContentID
JOIN RoUsages ROO on CAST(RON.ROID as int) = ROO.RoUsageID
where Len(RON.[ROID]) < 12
--print 'H ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- RoUsages are done
-- SELECT * From RoUsages where DTS = @DTS and UserID = @UserID
-- <<< Copy Transtions >>>
-- Note that the inserted record has the 'TranType' field set to old transitionid. This is done
-- so that the next step can replace the old transitionid with the new transitionid in the
-- content record's transition tokens. The TranType gets reset after the content records are
-- updated.
-- Also note that the 'toid/rangeid' may need converted to newly copied ids or may not. If it's
-- not a range, then it always is converted to new, if there is a new. If it's a range, both
-- the toid & the rangeid must be new in order for the conversion to be correct. You cannot
-- have part of the range pointing to the new and part of the range pointing to the original
-- locations.
INSERT INTO .[dbo].[Transitions] ([FromID],[ToID],[RangeID],[IsRange],[TranType],[Config],[DTS],[UserID])
SELECT NNF.[NewContentID],
-- if both toid & range are null, use the original toid & rangeid
CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [ToID] ELSE NNT.[NewItemID] END,
CASE WHEN NNT.[NewItemID] is null or NNR.[NewItemID] is null THEN [RangeID] ELSE NNR.[NewItemID] END,
[IsRange],[TransitionID],[Config],@DTS,@UserID
FROM .[dbo].[Transitions] TT
JOIN @Children NNF on TT.[FromID] = NNF.[ContentID]
LEFT JOIN @Children NNT on TT.[ToID] = NNT.[ItemID]
LEFT JOIN @Children NNR on TT.[RangeID] = NNR.[ItemID]
--print 'H1 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- -- Update content records for newly copied records to use correct TransitionIDs in the Transition tags
SET @RowsAffected=1
WHILE @RowsAffected > 0
BEGIN
UPDATE CC SET [TEXT] = C2.NewText
FROM CONTENTS CC
JOIN (SELECT C1.ContentID, .dbo.vefn_FixTransitionTextForCopy(C1.Text, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewText
FROM CONTENTS C1
JOIN @Children NN on C1.ContentID = NN.NewContentID
JOIN Transitions TR on NN.NewContentID = TR.FromID
JOIN Transitions TRO on TR.TranType = TRO.TransitionID) C2 ON CC.ContentID = C2.ContentID
WHERE [TEXT] <> C2.NewText
SET @RowsAffected = @@RowCount
END
--print 'H2 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
--set nocount off
-- -- Update grid records for newly copied records to use correct TransitionIDs in the Transition tags
declare @grids table
(
contentid int primary key,
data xml
)
insert into @grids select gg.contentid,gg.data from GRIDS GG
where gg.contentid in (select nn.newcontentid from
@Children NN
JOIN Transitions TR on NN.NewContentID = TR.FromID
JOIN Transitions TRO on TR.TranType = TRO.TransitionID)
--print 'H2.1 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
--select * from @grids
SET @RowsAffected=1
WHILE @RowsAffected > 0
BEGIN
UPDATE GG SET [DATA] = G2.NewData
FROM @GRIDS GG
JOIN (SELECT G1.ContentID, .dbo.vefn_FixTransitionDataForCopy(G1.Data, TRO.TransitionID, TRO.TranType, TRO.[ToID], TRO.[RangeID],TR.[TransitionID], TR.[ToID], TR.[RangeID], .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)) NewData
FROM @GRIDS G1
JOIN @Children NN on G1.ContentID = NN.NewContentID
JOIN Transitions TR on NN.NewContentID = TR.FromID
JOIN Transitions TRO on TR.TranType = TRO.TransitionID) G2 ON GG.ContentID = G2.ContentID
WHERE Cast([DATA] as nvarchar(max)) <> CAST(G2.NewData as nvarchar(max))
SET @RowsAffected = @@RowCount
END
--print 'H2.2 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
update GG set data = g1.data from Grids gg join @grids g1 on gg.contentid = g1.contentid
--print 'H3 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
--set nocount on
-- 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 whose transition format changes
INSERT INTO [Annotations] ([ItemID],[TypeID],[SearchText],[UserID])
SELECT NN.NewItemID, @typeID,'Verify Transition Format',@UserID
FROM Transitions TR
JOIN @Children NN on TR.FromID = NN.NewContentID
JOIN Transitions TRO on TR.TranType = TRO.TransitionID
WHERE .dbo.vefn_CompareTranFormat(NN.FormatID, NN.NewFormatID, TRO.TranType) <> 0
--print 'H4 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
UPDATE TR SET TR.[TranType] = .dbo.vefn_GetNewTranType(NN.FormatID, NN.NewFormatID, TRO.TranType)
FROM Transitions TR
JOIN @Children NN on TR.FromID = NN.NewContentID
JOIN Transitions TRO on TR.TranType = TRO.TransitionID
--print 'H5 ' + cast(datediff(s,@dts,getdate()) as varchar(100))
-- Transitions are done
-- SELECT * From Transitions where DTS = @DTS and UserID = @UserID
--print 'Z ' + cast(datediff(s,@dts,getdate()) as varchar(100))
--foldouts fixing code
if exists (select * from contents where contentid in (select newcontentid from @children) and config like '%FloatingFoldout%')
begin
--insert into #mytemp
select cc.contentid,xsteps.value('@FloatingFoldout','int') oldfoldoutid,(select newitemid
from @children
where itemid = xsteps.value('@FloatingFoldout','int')) newfoldoutid,xconfig
into #mytemp
from (select *,cast(config as xml) xconfig from contents where contentid in (select newcontentid from @children)) cc
cross apply xconfig.nodes('Config/Step') tsteps(xsteps)
--build @cmd string
declare @cmd nvarchar(max)
declare cmds cursor for
select distinct 'update #mytemp set xconfig.modify(''replace value of (Config/Step/@FloatingFoldout)[1] with "'
+ cast(newfoldoutid as varchar(10))
+ '"'') where xconfig.value(''(Config/Step/@FloatingFoldout)[1]'',''int'') = '
+ cast(oldfoldoutid as varchar(10))
from #mytemp
--execute cursor over rows
open cmds
fetch next from cmds into @cmd
while @@fetch_status = 0
begin
exec sp_executesql @cmd
fetch next from cmds into @cmd
end
close cmds
deallocate cmds
--actually update contents
update cc set config = cast(xconfig as varchar(max)) from contents cc join #mytemp mt on cc.contentid = mt.contentid
--get rid of #mytemp
drop table #mytemp
end
--end foldouts fixing code
--section start
DECLARE @NewContentID int
Select @NewContentID = NewContentID from @Children where ItemID = @StartItemID
DECLARE @Config varchar(max)
DECLARE @XConfig xml
select @Config = config from contents where contentid = @NewContentID
select @XConfig = cast(@Config as xml)
if @Config like '%SectionStart%' begin
DECLARE @SectionStart int
select @SectionStart = xproc.value('@SectionStart','int') from @xconfig.nodes('Config/Procedure') tproc(xproc)
DECLARE @NewSectionStart int
select @NewSectionStart = newitemid from @children where itemid = @SectionStart
DECLARE @cmd2 nvarchar(max)
set @cmd2 = '
declare @XConfig xml;
set @XConfig = cast(''' + @Config + ''' as xml);
set @XConfig.modify(''replace value of (Config/Procedure/@SectionStart)[1] with "' + cast(@NewSectionStart as nvarchar(10)) + '"'');
update contents set config = cast(@XConfig as varchar(max)) where contentid = ' + cast(@NewContentID as nvarchar(10)) + ';'
exec sp_executesql @cmd2
end
--end section start
IF( @@TRANCOUNT > 0 ) COMMIT
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
IF (@@Error = 0) PRINT 'Procedure Creation: [CopyItemAndChildren] Succeeded'
ELSE PRINT 'Procedure Creation: [CopyItemAndChildren] Error on Creation'
GO
/*
==========================================================================================================
End: C2024-004: KL - Update Copy Replace functionality, (remove ''copy of'')
==========================================================================================================
*/
-----------------------------------------------------------------------------
/*
---------------------------------------------------------------------------