From 4c399aaf0d88c10bff49f44ef268717ce1635ee9 Mon Sep 17 00:00:00 2001 From: Kyle Spearrin Date: Fri, 20 Jul 2018 23:08:10 -0400 Subject: [PATCH] new grant cleanup sproc --- src/Sql/Sql.sqlproj | 1 + .../Stored Procedures/Grant_DeleteExpired.sql | 19 ++++++++++ src/Sql/dbo/Tables/Grant.sql | 4 ++ .../2018-06-11_00_WebVaultUpdates.sql | 37 +++++++++++++++++++ 4 files changed, 61 insertions(+) create mode 100644 src/Sql/dbo/Stored Procedures/Grant_DeleteExpired.sql diff --git a/src/Sql/Sql.sqlproj b/src/Sql/Sql.sqlproj index 35379083b3..b467380cfe 100644 --- a/src/Sql/Sql.sqlproj +++ b/src/Sql/Sql.sqlproj @@ -228,5 +228,6 @@ + \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/Grant_DeleteExpired.sql b/src/Sql/dbo/Stored Procedures/Grant_DeleteExpired.sql new file mode 100644 index 0000000000..2d7c381e58 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Grant_DeleteExpired.sql @@ -0,0 +1,19 @@ +CREATE PROCEDURE [dbo].[Grant_DeleteExpired] +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + DECLARE @Now DATETIME2(7) = GETUTCDATE() + + WHILE @BatchSize > 0 + BEGIN + DELETE TOP(@BatchSize) + FROM + [dbo].[Grant] + WHERE + [ExpirationDate] < @Now + + SET @BatchSize = @@ROWCOUNT + END +END \ No newline at end of file diff --git a/src/Sql/dbo/Tables/Grant.sql b/src/Sql/dbo/Tables/Grant.sql index d63c881a71..6ec3552291 100644 --- a/src/Sql/dbo/Tables/Grant.sql +++ b/src/Sql/dbo/Tables/Grant.sql @@ -14,3 +14,7 @@ GO CREATE NONCLUSTERED INDEX [IX_Grant_SubjectId_ClientId_Type] ON [dbo].[Grant]([SubjectId] ASC, [ClientId] ASC, [Type] ASC); +GO +CREATE NONCLUSTERED INDEX [IX_Grant_ExpirationDate] + ON [dbo].[Grant]([ExpirationDate] ASC); + diff --git a/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql b/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql index 71cdb2f892..46078876dd 100644 --- a/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql +++ b/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql @@ -17,6 +17,16 @@ BEGIN END GO +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Grant_ExpirationDate' + AND object_id = OBJECT_ID('[dbo].[Grant]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Grant_ExpirationDate] + ON [dbo].[Grant]([ExpirationDate] ASC) +END +GO + IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'UserView') BEGIN DROP VIEW [dbo].[UserView] @@ -31,6 +41,33 @@ FROM [dbo].[User] GO +IF OBJECT_ID('[dbo].[Grant_DeleteExpired]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Grant_DeleteExpired] +END +GO + +CREATE PROCEDURE [dbo].[Grant_DeleteExpired] +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + DECLARE @Now DATETIME2(7) = GETUTCDATE() + + WHILE @BatchSize > 0 + BEGIN + DELETE TOP(@BatchSize) + FROM + [dbo].[Grant] + WHERE + [ExpirationDate] < @Now + + SET @BatchSize = @@ROWCOUNT + END +END +GO + IF OBJECT_ID('[dbo].[User_Create]') IS NOT NULL BEGIN DROP PROCEDURE [dbo].[User_Create]