From 8a5a8cc8b34d0ccee569f7c24bc4778b0fc8575a Mon Sep 17 00:00:00 2001 From: Rich Date: Sat, 14 Jun 2014 01:10:08 +0000 Subject: [PATCH] Modified stored procedures vesp_SessionBegin and vesp_SessionCanCheckOutItem to manage when an adminstrator can export or import a docversion from within PROMS. --- PROMS/DataLoader/PROMSFixes.Sql | 180 +++++++++++++++++++------------- 1 file changed, 107 insertions(+), 73 deletions(-) diff --git a/PROMS/DataLoader/PROMSFixes.Sql b/PROMS/DataLoader/PROMSFixes.Sql index 710a671a..cf3e4216 100644 --- a/PROMS/DataLoader/PROMSFixes.Sql +++ b/PROMS/DataLoader/PROMSFixes.Sql @@ -7672,29 +7672,46 @@ CREATE PROCEDURE [dbo].[vesp_SessionBegin] WITH EXECUTE AS OWNER AS BEGIN TRY -- Try Block - BEGIN TRANSACTION - --delete old closed sessions - DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is not null - --delete old owners from inactive sessions - DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate())) - DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate())) - --delete inactive sessions where last activity is before 15 minutes ago - DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate()) - DELETE FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate()) - INSERT INTO [Sessions]([UserID],[MachineName],[ProcessID]) - VALUES (@UserID, @MachineName, @ProcessID) - SELECT - [SessionID], - [UserID], - [DTSDtart], - [DTSEnd], - [DTSActivity], - [LastChanged], - [MachineName], - [ProcessID] - FROM [Sessions] - WHERE [SessionID]=SCOPE_IDENTITY() - IF( @@TRANCOUNT > 0 ) COMMIT + DECLARE @oCount int + SELECT @oCount = count(*) FROM Owners WHERE OwnerType = 3 + IF @oCount > 0 BEGIN + SELECT + [SessionID], + [UserID], + [DTSDtart], + [DTSEnd], + [DTSActivity], + [LastChanged], + [MachineName], + [ProcessID] + FROM [Sessions] + WHERE [SessionID]=0 + END + ELSE BEGIN + BEGIN TRANSACTION + --delete old closed sessions + DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is not null + --delete old owners from inactive sessions + DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate())) + DELETE FROM Owners WHERE SessionID in (SELECT SessionID FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate())) + --delete inactive sessions where last activity is before 15 minutes ago + DELETE FROM Sessions WHERE UserID = @UserID and DTSEnd is null and DTSActivity < DATEADD(minute, -5, getdate()) + DELETE FROM Sessions WHERE DTSEnd is null and DTSActivity < DATEADD(minute, -15, getdate()) + INSERT INTO [Sessions]([UserID],[MachineName],[ProcessID]) + VALUES (@UserID, @MachineName, @ProcessID) + SELECT + [SessionID], + [UserID], + [DTSDtart], + [DTSEnd], + [DTSActivity], + [LastChanged], + [MachineName], + [ProcessID] + FROM [Sessions] + WHERE [SessionID]=SCOPE_IDENTITY() + IF( @@TRANCOUNT > 0 ) COMMIT + END END TRY BEGIN CATCH -- Catch Block IF( @@TRANCOUNT = 1 ) ROLLBACK -- Only rollback if top level @@ -8043,57 +8060,74 @@ BEGIN ( SessionID int ) ---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 = @ObjectID 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(4)) FROM Owners WHERE OwnerType = 2 - IF ISNULL(@VersionIDList,'') != '' AND @ObjectType = 0 BEGIN --procedure - 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 = @ObjectID - 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 = @ObjectID - END ---look to see if object type is docversion that no part of docversion passed is checked out - IF @ObjectType = 2 BEGIN - --see what procedures maybe checked out - INSERT INTO @CheckOuts - SELECT ss.SessionID FROM dbo.vefn_GetVersiONItems(@ObjectID) 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(@ObjectID) 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 + --look to see if anyone else has a session. if they do, then cannot check out + DECLARE @sCount int + SELECT @sCount = count(*) FROM Sessions + IF @ObjectType = 3 BEGIN + SELECT + [SessionID], + [UserID], + [DTSDtart], + [DTSEnd], + [DTSActivity], + [LastChanged], + [MachineName], + [ProcessID] + FROM [Sessions] + WHERE DTSEnd IS NULL + END ELSE BEGIN + --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 = @ObjectID 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(4)) FROM Owners WHERE OwnerType = 2 + IF ISNULL(@VersionIDList,'') != '' AND @ObjectType = 0 BEGIN --procedure + 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 = @ObjectID + 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 = @ObjectID + END + --look to see if object type is docversion that no part of docversion passed is checked out + IF @ObjectType = 2 BEGIN + --see what procedures maybe checked out + INSERT INTO @CheckOuts + SELECT ss.SessionID FROM dbo.vefn_GetVersiONItems(@ObjectID) 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(@ObjectID) 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 - SELECT - [SessionID], - [UserID], - [DTSDtart], - [DTSEnd], - [DTSActivity], - [LastChanged], - [MachineName], - [ProcessID] - FROM [Sessions] - WHERE [SessionID] IN (SELECT SessionID FROM @CheckOuts) + SELECT + [SessionID], + [UserID], + [DTSDtart], + [DTSEnd], + [DTSActivity], + [LastChanged], + [MachineName], + [ProcessID] + FROM [Sessions] + WHERE [SessionID] IN (SELECT SessionID FROM @CheckOuts) + END END GO -- Display the status of Proc creation