tr_tblContents_Update - Limit Change Manager Content Audits when Config is not being changed for Export or Enhanced nodes
vesp_BuildDocVersionExport - Setup Export nodes (Creation Date and Time) in the DocVersion records for Enhanced Documents vesp_BuildContentsExport - Setup Export nodes (LinkID) in the Content records for Enahnced Documents vesp_BuildContentsEnhanced- Setup Enhanced nodes after Export / Import
This commit is contained in:
parent
e0203c1a77
commit
f3ac8c9a42
@ -13413,6 +13413,356 @@ go
|
||||
IF (@@Error = 0) PRINT 'TableFunction [vefn_GetZeroFromType] Succeeded'
|
||||
ELSE PRINT 'TableFunction [vefn_GetZeroFromType] Error on Creation'
|
||||
|
||||
GO
|
||||
|
||||
-- B2017-227 Added code to support Export/Import of Enhanced Documents
|
||||
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2017 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
/****** Object: Trigger [tr_tblContents_Update] ******/
|
||||
ALTER trigger [dbo].[tr_tblContents_Update] on [dbo].[tblContents] for update as
|
||||
begin
|
||||
if exists (select * from inserted)
|
||||
begin
|
||||
if update(Number) or update(Text) or update(Type) or update(FormatID) or update(DeleteStatus)
|
||||
begin
|
||||
insert into ContentAudits(ContentID,Number,Text,Type,FormatID,Config,DTS,UserID,DeleteStatus,ActionDTS)
|
||||
select dd.ContentID,dd.Number,dd.Text,dd.Type,dd.FormatID,dd.Config,dd.DTS,dd.UserID,dd.DeleteStatus,dd.ActionDTS
|
||||
from deleted dd
|
||||
inner join inserted ii on dd.ContentID = ii.ContentID
|
||||
where dd.Text not like '%<CROUSGID=%' and dd.Text not like '%<CTID=%'
|
||||
--and (select count(*) from contentaudits where contentid = dd.contentid and dts = dd.dts and deletestatus = dd.deletestatus) = 0
|
||||
and (select count(*) from contentaudits where contentid = dd.contentid and dts = dd.dts and ActionDTS = dd.ActionDTS) = 0
|
||||
end
|
||||
else if update(Config) -- Only save audits for changes to Config when the changes are not for Enhanced or Export Nodes
|
||||
begin
|
||||
-- Temporary Table containing xml of Config for the before and after values of the config
|
||||
declare @Compare TABLE
|
||||
(
|
||||
ContentID int,
|
||||
dXml xml,
|
||||
iXml xml
|
||||
)
|
||||
-- Build the compare table
|
||||
insert into @Compare
|
||||
select DD.ContentID, cast(DD.Config as xml) dXML, cast(II.Config as xml) iXML from Deleted DD
|
||||
inner join inserted ii on dd.ContentID = ii.ContentID
|
||||
-- delete Export Nodes
|
||||
update @Compare set dXml.modify('delete //Export'),iXml.modify('delete //Export')
|
||||
-- delete Enahnced Nodes
|
||||
update @Compare set dXml.modify('delete //Enhanced'),iXml.modify('delete //Enhanced')
|
||||
--remove from temporary table where there are no differences
|
||||
delete from @Compare where cast(dXml as nvarchar(max)) = cast(iXml as nvarchar(max))
|
||||
-- add audits for remaining changes
|
||||
insert into ContentAudits(ContentID,Number,Text,Type,FormatID,Config,DTS,UserID,DeleteStatus,ActionDTS)
|
||||
select dd.ContentID,dd.Number,dd.Text,dd.Type,dd.FormatID,dd.Config,dd.DTS,dd.UserID,dd.DeleteStatus,dd.ActionDTS
|
||||
from deleted dd
|
||||
inner join inserted ii on dd.ContentID = ii.ContentID
|
||||
where DD.ContentID in(Select ContentID from @Compare)
|
||||
end
|
||||
end
|
||||
end
|
||||
GO
|
||||
|
||||
-- Display the status of Trigger alter
|
||||
IF (@@Error = 0) PRINT 'Trigger Ateration: tr_tblContents_Update Succeeded'
|
||||
ELSE PRINT 'Trigger Ateration: tr_tblContents_Update Error on Creation'
|
||||
GO
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[vesp_BuildDocVersionExport]') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_BuildDocVersionExport];
|
||||
GO
|
||||
/*
|
||||
select DV.VersionID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from DocVersions) DV
|
||||
cross apply xconfig.nodes('//Export') tExport(xExport)
|
||||
EXEC [vesp_BuildDocVersionExport] 13
|
||||
select DV.VersionID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from DocVersions) DV
|
||||
cross apply xconfig.nodes('//Export') tExport(xExport)
|
||||
*/
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2017 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
|
||||
-- Add Export Created Date and Time to the Source DocVersion record and to the Enhanced DocVersion records
|
||||
|
||||
CREATE PROCEDURE [dbo].[vesp_BuildDocVersionExport](@SourceID int)
|
||||
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN TRY -- Try Block
|
||||
BEGIN TRANSACTION
|
||||
-- Temporary Table including VersionID and config as xml (xconfig)
|
||||
-- This allows previous Export nodes to be removed
|
||||
Declare @DV TABLE
|
||||
(
|
||||
VersionID int,
|
||||
xConfig xml
|
||||
)
|
||||
-- Initialize @DV Table - Get Source Record and any Enhanced Records that have the specified SourceID
|
||||
insert into @DV
|
||||
select VersionID, xConfig from (Select *, Cast(config as xml) xconfig from DocVersions) DV
|
||||
where VersionID = @SourceID
|
||||
Union ALL
|
||||
select VersionID, xConfig from (Select *, Cast(config as xml) xconfig from DocVersions) DV
|
||||
cross apply xConfig.nodes('//Enhanced[@VersionID=sql:variable("@SourceID")]') tEnhanced(xEnhanced)
|
||||
-- Remove Export Node
|
||||
update @DV Set xConfig.modify('delete //Export') From @DV
|
||||
-- Create Export Node
|
||||
Declare @ExportNode nvarchar(60)
|
||||
-- Create an Export node to be applied to the Source and Enhanced DocVersion records
|
||||
Set @ExportNode = '<Export Created="' + Convert(nvarchar(23),getdate(),121) + '"/>'
|
||||
-- Insert Export Node into the Source and Enhanced DocVersion records
|
||||
Update DV set Config = Replace(Cast(xConfig as nvarchar(max)),'</Config>',@ExportNode + '</Config>')
|
||||
from DocVersions DV
|
||||
Join @DV DV2 on DV2.VersionID = DV.VersionID
|
||||
|
||||
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
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'StoredProcedure [vesp_BuildDocVersionExport] Succeeded'
|
||||
ELSE PRINT 'StoredProcedure [vesp_BuildDocVersionExport] Error on Creation'
|
||||
go
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'vesp_BuildContentsExport') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_BuildContentsExport];
|
||||
GO
|
||||
/*
|
||||
select Count(*) AuditsBefore from ContentAudits
|
||||
select top 5 CC.ContentID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from Contents) CC
|
||||
cross apply xconfig.nodes('//Export') tExport(xExport)
|
||||
EXEC [vesp_BuildContentsExport] 13
|
||||
select Count(*) AuditsAfter from ContentAudits
|
||||
select top 5 CC.ContentID, xExport.query('.') qExport from (select *, Cast(config as xml) xconfig from Contents) CC
|
||||
cross apply xconfig.nodes('//Export') tExport(xExport)
|
||||
*/
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2017 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
|
||||
-- Add Unique IDs for Each Enhanced Link in the Contents records
|
||||
|
||||
CREATE PROCEDURE [dbo].[vesp_BuildContentsExport](@SourceID int)
|
||||
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN TRY -- Try Block
|
||||
BEGIN TRANSACTION
|
||||
-- Update the DocVersion Records as the Content records are being saved with the Export node
|
||||
Exec vesp_BuildDocVersionExport @SourceID
|
||||
-- Create a list of Source and Enhanced VersionIDs
|
||||
declare @VersionList varchar(max)
|
||||
select @VersionList = Coalesce(@VersionList+',','') + cast(VersionId as varchar(10)) from (
|
||||
select VersionID from DocVersions DV
|
||||
where VersionID = @SourceID
|
||||
Union
|
||||
select VersionID from (Select *, Cast(config as xml) xConfig from DocVersions) DV
|
||||
cross apply xConfig.nodes('//Enhanced[@VersionID=sql:variable("@SourceID")]') tEnhanced(xEnhanced)) T1
|
||||
-- Temporary table of ContentID and config as XML for record in the Specified DocVersion VersionIDs that have Export Nodes
|
||||
Declare @Config TABLE
|
||||
(
|
||||
ContentID int,
|
||||
xConfig xml
|
||||
)
|
||||
-- Build the temporary table
|
||||
Insert into @Config
|
||||
select CC.ContentID, xconfig from (select *, cast(config as xml) xConfig from Contents) CC
|
||||
JOIN VEFN_GetVersionItems(@VersionList) VI ON VI.ContentID = CC.ContentID
|
||||
cross Apply xConfig.nodes('//Export') tExport(xExport)
|
||||
-- Delete the existing Export nodes so that the new nodes can be added.
|
||||
update @Config Set xConfig.modify('delete //Export') From @Config
|
||||
-- Update the Config field in the Content records with the old Export node removed.
|
||||
update CC set Config = cast(xConfig as NVarchar(max)) from Contents CC
|
||||
join @Config C1 ON C1.ContentID = CC.ContentID
|
||||
-- Temporary table with new link nodes
|
||||
Declare @NewLinkData TABLE
|
||||
(
|
||||
ContentID int,
|
||||
EContentID int,
|
||||
ItemLink int,
|
||||
LinkNode nvarchar(250)
|
||||
)
|
||||
-- The following code build the Export node based upon Dense_Rank() which is similar to a record count
|
||||
-- only it is based upon the Source ItemID and returns a unique integer value
|
||||
insert into @NewLinkData
|
||||
select distinct t1.ContentID, II.ContentID EContentID
|
||||
, DENSE_RANK() Over (Order by t1.ItemID) ItemLink
|
||||
, '<Export LinkID="' + cast(DENSE_RANK() Over (Order by t1.ItemID) as nvarchar(250)) + '"/>' LinkNode
|
||||
From (
|
||||
select ItemID, vi.VersionID, VI.ContentID, xEnhanced.query('.') qEnhanced
|
||||
,xEnhanced.value('@Type','int') EType
|
||||
,xEnhanced.value('@ItemID','int') EItemID
|
||||
from (Select *, cast(config as xml) xconfig from Contents where config Like '%Enhanced%') CC
|
||||
JOIN VEFN_GetVersionItems(cast(@SourceID as nvarchar(10))) VI ON VI.ContentID = CC.ContentID
|
||||
cross Apply xConfig.nodes('//Enhanced') tEnhanced(xEnhanced)) T1
|
||||
JOIN Items II ON II.ItemID = EItemID
|
||||
Where EType!=0
|
||||
-- Add the Export Node created in the temprorary table for the Source document
|
||||
Update CC
|
||||
set Config = Replace(Config,'</Config>',LinkNode + '</Config>')
|
||||
From tblContents CC
|
||||
Join @NewLinkData LD ON LD.ContentID = CC.ContentID
|
||||
-- Add the Export Node created in the tempoary table for the Enhanced document
|
||||
Update CC
|
||||
set Config = Replace(Config,'</Config>',LinkNode + '</Config>')
|
||||
From tblContents CC
|
||||
Join @NewLinkData LD ON LD.EContentID = CC.ContentID
|
||||
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
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'StoredProcedure [vesp_BuildContentsExport] Succeeded'
|
||||
ELSE PRINT 'StoredProcedure [vesp_BuildContentsExport] Error on Creation'
|
||||
go
|
||||
|
||||
IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'vesp_BuildContentsEnhanced') AND OBJECTPROPERTY(id,N'IsProcedure') = 1)
|
||||
DROP PROCEDURE [vesp_BuildContentsEnhanced];
|
||||
GO
|
||||
/*
|
||||
select Count(*) AuditsBefore from ContentAudits
|
||||
select top 5 CC.ContentID, xEnhanced.query('.') qEnhanced from (select *, Cast(config as xml) xconfig from Contents) CC
|
||||
cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced)
|
||||
EXEC [vesp_BuildContentsEnhanced] 17
|
||||
select Count(*) AuditsAfter from ContentAudits
|
||||
select top 5 CC.ContentID, xEnhanced.query('.') qEnhanced from (select *, Cast(config as xml) xconfig from Contents) CC
|
||||
cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced)
|
||||
*/
|
||||
|
||||
/*****************************************************************************
|
||||
Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE
|
||||
Copyright 2017 - Volian Enterprises, Inc. All rights reserved.
|
||||
*****************************************************************************/
|
||||
|
||||
-- Create Enahnced Nodes for an Enahnced document and its related Source document
|
||||
|
||||
CREATE PROCEDURE [dbo].[vesp_BuildContentsEnhanced](@EnhancedID int)
|
||||
|
||||
WITH EXECUTE AS OWNER
|
||||
AS
|
||||
BEGIN TRY -- Try Block
|
||||
BEGIN TRANSACTION
|
||||
declare @SourceID int -- Source VersionID
|
||||
-- Get SourceID from EnhancedID
|
||||
select @SourceID = xEnhanced.value('@VersionID','int') from (select *, cast(config as xml) xconfig from DocVersions) DV
|
||||
cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced)
|
||||
where VersionID = @EnhancedID
|
||||
|
||||
DECLARE @EnhType int
|
||||
-- Get the Enhanced Type from the DocVersion record
|
||||
select @EnhType = xEnhanced.value('@Type','int')
|
||||
from (select *, cast(config as xml) xConfig from DocVersions where VersionID = @SourceID) DV
|
||||
cross apply xconfig.nodes('//Enhanced[@VersionID=sql:variable("@EnhancedID")]') tEnhanced(xEnhanced)
|
||||
-- Fix DocVersion Records
|
||||
-- Temporary Table used to delete old Enhanced Nodes in the source document
|
||||
declare @Enh1 TABLE
|
||||
(
|
||||
ID int,
|
||||
xConfig xml
|
||||
)
|
||||
insert into @Enh1 -- Links to Enhanced from Source
|
||||
select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC
|
||||
JOIN VEFN_GetVersionItems(cast(@SourceID as varchar(25))) VI ON VI.ContentID = CC.ContentID
|
||||
cross apply VEFN_GetNewEnhancedData(VI.itemid,@EnhType) VEN
|
||||
-- delete the Enhanced node from the config
|
||||
Update @Enh1 Set xConfig.modify('delete //Enhanced[@Type=sql:variable("@EnhType")]') From @Enh1
|
||||
-- Update the content record removing the Enhanced node from config
|
||||
Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Source
|
||||
Join @Enh1 EE ON EE.ID = CC.ContentID
|
||||
-- Temporary Table used to delete old Enhanced Nodes in the enhanced document
|
||||
declare @Enh2 TABLE
|
||||
(
|
||||
ID int,
|
||||
xConfig xml
|
||||
)
|
||||
insert into @Enh2 -- Links to Source from Enhanced
|
||||
select CC.ContentID, xConfig from (select *, cast(config as xml) xConfig from Contents) CC
|
||||
JOIN VEFN_GetVersionItems(cast(@EnhancedID as varchar(25))) VI ON VI.ContentID = CC.ContentID
|
||||
cross apply VEFN_GetNewEnhancedData(VI.itemid,0) VEN
|
||||
--set @EnhType=0
|
||||
-- delete the Enhanced node from the config
|
||||
Update @Enh2 Set xConfig.modify('delete //Enhanced[@Type=0]') From @Enh2
|
||||
-- Update the content record removing the Enhanced node from config
|
||||
Update CC Set Config = cast(xconfig as varchar(max)) From Contents CC -- Remove Links from Enhanced
|
||||
Join @Enh2 EE ON EE.ID = CC.ContentID
|
||||
-- Temporary Table used to store the Export LinkID with the ContentID and the ItemID for the Source Document
|
||||
declare @Source TABLE
|
||||
(
|
||||
Type int,
|
||||
ContentID int,
|
||||
ItemID int,
|
||||
LinkID int primary Key
|
||||
)
|
||||
-- Build the table based upon the Export Nodes in the Source document
|
||||
insert into @Source
|
||||
Select @EnhType dvType, CC.ContentID, vi.ItemID, xExport.value('@LinkID','int') LinkID
|
||||
from (select *, cast(config as xml) xConfig from Contents) CC
|
||||
JOIN VEFN_GetVersionItems(cast(@SourceID as varchar(10))) VI ON VI.ContentID = CC.ContentID
|
||||
Join (select *, cast(config as xml)xdvConfig from DocVersions) DV ON VI.VersionID= DV.VersionID
|
||||
cross apply xConfig.nodes('//Export') tExport(xExport)
|
||||
--cross apply xDVConfig.nodes('//Enhanced') tdvEnhanced(xdvEnhanced)
|
||||
-- Temporary Table used to store the Export LinkID with the ContentID and the ItemID for the Enhanced Document
|
||||
declare @Enhanced TABLE
|
||||
(
|
||||
Type int,
|
||||
ContentID int,
|
||||
ItemID int,
|
||||
LinkID int primary key
|
||||
)
|
||||
-- Build the table based upon the Export Nodes in the Enhanced document
|
||||
insert into @Enhanced
|
||||
Select xdvEnhanced.value('@Type','int') dvType, CC.ContentID, vi.ItemID, xExport.value('@LinkID','int') LinkID
|
||||
from (select *, cast(config as xml) xConfig from Contents) CC
|
||||
JOIN VEFN_GetVersionItems(cast(@EnhancedID as varchar(10))) VI ON VI.ContentID = CC.ContentID
|
||||
Join (select *, cast(config as xml)xdvConfig from DocVersions) DV ON VI.VersionID= DV.VersionID
|
||||
cross apply xConfig.nodes('//Export') tExport(xExport)
|
||||
cross apply xDVConfig.nodes('//Enhanced') tdvEnhanced(xdvEnhanced)
|
||||
-- Temporary Table of ContentIDs and New Enhanced Node Text
|
||||
declare @Links TABLE
|
||||
(
|
||||
ContentID int primary key,
|
||||
LinkText nvarchar(250)
|
||||
)
|
||||
--Build the temporary table with the new enhanced Nodes
|
||||
insert into @links
|
||||
select SS.ContentID, '<Enhanced Type="' + cast(SS.Type as varchar(10)) +'" ItemID="' + cast(EE.ItemID as varchar(10)) + '" />' EnhancedNode from @Source SS
|
||||
join @Enhanced EE on EE.LinkID = SS.LinkID
|
||||
UNION
|
||||
select EE.ContentID, '<Enhanced Type="' + cast(EE.Type as varchar(10)) +'" ItemID="' + cast(SS.ItemID as varchar(10)) + '" />' EnhancedNode from @Source SS
|
||||
join @Enhanced EE on EE.LinkID = SS.LinkID
|
||||
-- Update content records insering the Enhanced Nodes from the temporary table.
|
||||
Update CC
|
||||
set Config = Replace(Config,'</Config>',LinkText + '</Config>')
|
||||
From Contents CC
|
||||
Join @Links LD ON LD.ContentID = CC.ContentID
|
||||
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
|
||||
-- Display the status of Proc creation
|
||||
IF (@@Error = 0) PRINT 'StoredProcedure [vesp_BuildContentsEnhanced] Succeeded'
|
||||
ELSE PRINT 'StoredProcedure [vesp_BuildContentsEnhanced] Error on Creation'
|
||||
go
|
||||
|
||||
-----------------------------------------------------------------------------
|
||||
/*
|
||||
@ -13439,8 +13789,8 @@ BEGIN TRY -- Try Block
|
||||
set nocount on
|
||||
DECLARE @RevDate varchar(255)
|
||||
DECLARE @RevDescription varchar(255)
|
||||
set @RevDate = '9/15/2017 8:00 AM'
|
||||
set @RevDescription = 'Corrected Definitions that were using default schema'
|
||||
set @RevDate = '9/30/2017 8:00 AM'
|
||||
set @RevDescription = 'Enhanced Export Import'
|
||||
Select cast(@RevDate as datetime) RevDate, @RevDescription RevDescription
|
||||
PRINT 'SQL Code Revision ' + @RevDate + ' - ' + @RevDescription
|
||||
IF( @@TRANCOUNT > 0 ) COMMIT
|
||||
|
Loading…
x
Reference in New Issue
Block a user