From 0bcbbd92350d32b19fc03b296858be4ffdc3b80b Mon Sep 17 00:00:00 2001 From: Rich Date: Thu, 28 Jan 2016 16:16:55 +0000 Subject: [PATCH] Improved Checkout performance B2016-012 Bug Fixed. Not sure how, but the issue is no longer seen. --- PROMS/DataLoader/PROMSFixes.Sql | 186 ++++++++++++++------------------ 1 file changed, 81 insertions(+), 105 deletions(-) diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index e4565878..a4a3f4a3 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -7873,7 +7873,9 @@ BEGIN (select convert(bigint,max(lastchanged)) from contents) LastContentChange FROM [Sessions] WHERE DTSEnd IS NULL - END ELSE BEGIN + END + ELSE + BEGIN DECLARE @ObjectAndEnhancedIDs Table ( ObjectID int @@ -7881,105 +7883,89 @@ BEGIN IF @ObjectType = 0 BEGIN INSERT INTO @ObjectAndEnhancedIDs select ItemID from vefn_GetEnhancedProcedures(@ObjectID) - --select distinct itemid from - --items ii - --join (select *, cast(config as xml) xconfig from contents - --) cc on cc.contentid = ii.contentid - --cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) - --where cc.Type = 0 and (xEnhanced.value('@ItemID', 'int') = @ObjectID or - --itemid = @ObjectID) END ELSE IF @ObjectType = 2 BEGIN INSERT INTO @ObjectAndEnhancedIDs - select VersionID from vefn_GetEnhancedDocVersions(@ObjectID) - --select distinct versionid from - --(select *, cast(config as xml) xconfig from docversions) dv - --cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) - --where xEnhanced.value('@VersionID', 'int') = @ObjectID or versionid = @ObjectID + select VersionID from vefn_GetEnhancedDocVersions(@ObjectID) END ELSE IF @ObjectType = 3 BEGIN INSERT INTO @ObjectAndEnhancedIDs select FolderID from vefn_GetEnhancedFolders(@ObjectID) - --select distinct dv.folderid from - --(select *, cast(config as xml) xconfig from docversions) dv - --cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) - --join docversions denh on xEnhanced.value('@VersionID', 'int') = denh.VersionID - --where denh.FolderID = @ObjectID or dv.folderid = @ObjectID END ELSE BEGIN INSERT INTO @ObjectAndEnhancedIDs select @ObjectID END - --look to see if object is already checked out in owner table as passed object type INSERT INTO @CheckOuts SELECT DISTINCT SessionID FROM Owners WHERE OwnerItemID in (select ObjectID from @ObjectAndEnhancedIDs) AND OwnerType = @ObjectType - --look to see if object is part of a checked out docversion as passed object type - DECLARE @VersionIDList varchar(max) - SELECT @VersionIDList = COALESCE(@VersionIDList + ',','') + CAST(OwnerItemID as varchar(10)) FROM Owners WHERE OwnerType = 2 - IF ISNULL(@VersionIDList,'') != '' AND @ObjectType = 0 BEGIN --procedure + IF @ObjectType = 2 + BEGIN + with ItemZ (VersionID,ItemID,PreviousID,SessionID) + as( + --> Procedure Owners + select null,II.ItemID, PreviousID, SessionID + from Owners OO + Join Items II on OO.OwnerItemID= II.ItemID + Where OO.OwnerType=0 + UNION ALL --> Document Owners + select null,II.ItemID, PreviousID, SessionID + from Owners OO + Join Entries EE ON OO.OwnerItemID = EE.DocID + Join Items II on EE.ContentID= II.ContentID + Where OO.OwnerType=1 + UNION ALL --> Previous Owners + Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ + Join Items II ON II.ItemID = ZZ.PreviousID + Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL + UNION ALL -- Parts Owners + Select null, II.ItemID, II.PreviousID, ZZ.SessionID + from ItemZ ZZ + Join Parts PP ON PP.ItemID = ZZ.ItemID + Join Items II ON II.ContentID = PP.ContentID + Where ZZ.VersionID IS NULL + UNION ALL -- Version Owners + Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ + Join DocVersions DV ON ZZ.ItemID = DV.ItemID + Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL + ) + --Select Distinct 'Phase 2b' Result, * from Itemz INSERT INTO @CheckOuts - SELECT ss.SessionID FROM dbo.vefn_GetVersionItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Owners oo ON vi.VersionID = oo.OwnerItemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - WHERE cc.Type = 0 AND vi.ItemID in (select ObjectID from @ObjectAndEnhancedIDs) + Select DIstinct SessionID from ItemZ + where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) END - IF ISNULL(@VersionIDList,'') != '' AND @ObjectType = 1 BEGIN --document - INSERT INTO @CheckOuts - SELECT ss.SessionID FROM dbo.vefn_GetVersionItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Entries ee ON vi.ContentID = ee.ContentID - INNER JOIN Owners oo ON vi.VersionID = oo.OwneritemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - WHERE ee.DocID in (select ObjectID from @ObjectAndEnhancedIDs) - END - --look to see if object type is docversion that no part of docversion passed is checked out - IF @ObjectType = 2 BEGIN - SELECT @VersionIDList = COALESCE(@VersionIDList + ',','') + CAST(ObjectID as varchar(10)) FROM @ObjectAndEnhancedIDs - IF ISNULL(@VersionIDList,'') != '' BEGIN - --see what procedures maybe checked out - INSERT INTO @CheckOuts - SELECT ss.SessionID FROM dbo.vefn_GetVersiONItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Owners oo ON vi.ItemID = oo.OwnerItemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - WHERE cc.Type = 0 - --see what documents maybe checked out - INSERT INTO @CheckOuts - SELECT ss.SessionID FROM dbo.vefn_GetVersiONItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Entries ee ON vi.ContentID = ee.ContentID - INNER JOIN Owners oo ON ee.DocID = oo.OwnerItemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - END - END - --look to see if object type is folder that no part of folder passed is checked out + --look to see if object type is folder that no part of folder passed is checked out IF @ObjectType = 3 BEGIN - SELECT @VersionIDList = COALESCE(@VersionIDList + ',','') + CAST(VersionID as varchar(10)) - FROM DocVersions where FolderID in (SELECT ObjectID FROM @ObjectAndEnhancedIDs) - IF ISNULL(@VersionIDList,'') != '' BEGIN - --DECLARE @VersionID int - --SELECT @VersionID = VersionID from DocVersions - --WHERE FolderID in (select ObjectID from @ObjectAndEnhancedIDs) - -- Add this DocVersion to @Checkouts - INSERT INTO @CheckOuts SELECT DISTINCT SessionID FROM Owners - WHERE OwnerItemID in - (select VersionID from DocVersions where FolderID in (select ObjectID from @ObjectAndEnhancedIDs)) AND OwnerType = 2 - --see what procedures maybe checked out - INSERT INTO @CheckOuts - SELECT DISTINCT ss.SessionID FROM dbo.vefn_GetVersiONItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Owners oo ON vi.ItemID = oo.OwnerItemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - WHERE cc.Type = 0 and ss.SessionID not in (select SessionID FROM @CheckOuts) - --see what documents maybe checked out - INSERT INTO @CheckOuts - SELECT DISTINCT ss.SessionID FROM dbo.vefn_GetVersiONItems(@VersionIDList) vi - INNER JOIN Contents cc ON vi.ContentID = cc.ContentID - INNER JOIN Entries ee ON vi.ContentID = ee.ContentID - INNER JOIN Owners oo ON ee.DocID = oo.OwnerItemID - INNER JOIN Sessions ss ON oo.SessionID = ss.SessionID - WHERE ss.SessionID not in (select SessionID FROM @CheckOuts) - END + with ItemZ (VersionID,ItemID,PreviousID,SessionID) + as( + --> Procedure Owners + select null,II.ItemID, PreviousID, SessionID + from Owners OO + Join Items II on OO.OwnerItemID= II.ItemID + Where OO.OwnerType=0 + UNION ALL --> Document Owners + select null,II.ItemID, PreviousID, SessionID + from Owners OO + Join Entries EE ON OO.OwnerItemID = EE.DocID + Join Items II on EE.ContentID= II.ContentID + Where OO.OwnerType=1 + UNION ALL --> Previous Owners + Select null, ii.ItemID, ii.PreviousID,ZZ.SessionID From ItemZ ZZ + Join Items II ON II.ItemID = ZZ.PreviousID + Where ZZ.VersionID IS NULL and ZZ.PreviousID IS NOT NULL + UNION ALL -- Parts Owners + Select null, II.ItemID, II.PreviousID, ZZ.SessionID + from ItemZ ZZ + Join Parts PP ON PP.ItemID = ZZ.ItemID + Join Items II ON II.ContentID = PP.ContentID + Where ZZ.VersionID IS NULL + UNION ALL -- Version Owners + Select DV.VersionID,null,null,ZZ.SessionID From ItemZ ZZ + Join DocVersions DV ON ZZ.ItemID = DV.ItemID + Where ZZ.VersionID IS NULL AND ZZ.PreviousID IS NULL + ) + --Select Distinct 'Phase 2b' Result, * from Itemz + INSERT INTO @CheckOuts + Select DIstinct SessionID from ItemZ + where VersionID in(select ObjectID FROM @ObjectAndEnhancedIDs) END SELECT [SessionID], @@ -11213,25 +11199,15 @@ RETURNS @VersionItems TABLE WITH EXECUTE AS OWNER AS BEGIN - with Itemz([VersionID], [ItemID], [ContentID], [eItemID], [Level]) as - (Select DV.VersionID, [I].[ItemID], [I].[ContentID],xEnhanced1.value('@ItemID','int') eItemID, 0 Level - FROM [Items] I - Join (Select ContentID, cast(config as xml) xConfig from contents) c1 on i.cONTENTid = c1.ContentID - cross apply c1.xConfig.nodes('//Enhanced') tEnhanced1(xEnhanced1) - JOIN vefn_GetVersionItems('') DV ON I.[ItemID] = DV.[ItemID] - Where I.ItemID = @ItemID - Union All - -- Enhanced - select DV.VersionID, I2.[ItemID], I2.[ContentID],xEnhanced2.value('@ItemID','int') eItemID,Z.Level+1 - from Itemz Z - Join Items I2 ON I2.ItemID = z.eItemID - JOIN vefn_GetVersionItems('') DV ON I2.[ItemID] = DV.[ItemID] - Join (Select ContentID, cast(config as xml) xConfig from contents) c2 on i2.cONTENTid = c2.ContentID - cross apply c2.xConfig.nodes('//Enhanced') tEnhanced2(xEnhanced2) - Where Z.Level < 3 - ) + with ItemZ(ItemId, EnhID, Level) as + (Select ItemID,xEnhanced.value('@ItemID','int') EnhID, 0 from Items II Join (Select ContentID, cast(config as xml) xconfig From Contents) + CC On CC.ContentID = II.ContentID cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) Where ItemID = @ItemID + Union ALL + Select II.ItemID,xEnhanced.value('@ItemID','int') EnhID, ZZ.Level+1 from Items II Join ItemZ ZZ on ZZ.EnhID = II.ItemID + Join (Select ContentID, cast(config as xml) xconfig From Contents) CC On CC.ContentID = II.ContentID + cross apply xconfig.nodes('//Enhanced') tEnhanced(xEnhanced) Where zz.Level < 2) INSERT INTO @VersionItems - select distinct VersionID, ItemID, ContentID from Itemz + Select distinct dbo.vefn_GetVersionIDByItemID(ZZ.ItemID) VersionID, ZZ.ItemID, II.ContentID from ItemZ ZZ Join Items II on II.ItemID = ZZ.ItemID OPTION (MAXRECURSION 10000) RETURN END @@ -11258,7 +11234,7 @@ Select * from vefn_GetVersionTblItems('') */ /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE - Copyright 2013 - Volian Enterprises, Inc. All rights reserved. + Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE FUNCTION [dbo].[vefn_GetVersionTblItems](@DocVersionList varchar(MAX)) RETURNS @VersionItems TABLE @@ -11309,7 +11285,7 @@ GO /***************************************************************************** Volian Enterprises - Proprietary Information - DO NOT COPY OR DISTRIBUTE - Copyright 2012 - Volian Enterprises, Inc. All rights reserved. + Copyright 2016 - Volian Enterprises, Inc. All rights reserved. *****************************************************************************/ CREATE PROCEDURE [dbo].[vesp_PurgeDisconnectedData] WITH EXECUTE AS OWNER @@ -11376,4 +11352,4 @@ END CATCH IF (@@Error = 0) PRINT 'Procedure Creation: vesp_PurgeDisconnectedData Succeeded' ELSE PRINT 'Procedure Creation: vesp_PurgeDisconnectedData Error on Creation' GO -PRINT '20150808 Improved performance for delete procedure' +PRINT '20160126 Improved performance for checkouts'