From ebb1f9e1a8466b4c460e29fb54f57ced565c4b14 Mon Sep 17 00:00:00 2001 From: Kyle Spearrin Date: Tue, 12 Jun 2018 13:24:13 -0400 Subject: [PATCH] use temp tables for better execution plans --- .../Organization_UpdateStorage.sql | 29 +++-- .../Stored Procedures/User_UpdateStorage.sql | 25 +++- .../2018-06-11_00_WebVaultUpdates.sql | 117 ++++++++++++++++++ 3 files changed, 157 insertions(+), 14 deletions(-) diff --git a/src/Sql/dbo/Stored Procedures/Organization_UpdateStorage.sql b/src/Sql/dbo/Stored Procedures/Organization_UpdateStorage.sql index f74253b6d8..ece4bc9464 100644 --- a/src/Sql/dbo/Stored Procedures/Organization_UpdateStorage.sql +++ b/src/Sql/dbo/Stored Procedures/Organization_UpdateStorage.sql @@ -6,6 +6,22 @@ BEGIN DECLARE @Storage BIGINT + CREATE TABLE #Temp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #Temp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] IS NULL + AND [OrganizationId] = @Id + ;WITH [CTE] AS ( SELECT [Id], @@ -16,17 +32,14 @@ BEGIN OPENJSON([Attachments]) ) [Size] FROM - [dbo].[Cipher] + #Temp ) SELECT - @Storage = SUM([CTE].[Size]) + @Storage = SUM([Size]) FROM - [dbo].[Cipher] C - LEFT JOIN - [CTE] ON C.[Id] = [CTE].[Id] - WHERE - C.[UserId] IS NULL - AND C.[OrganizationId] = @Id + [CTE] + + DROP TABLE #Temp UPDATE [dbo].[Organization] diff --git a/src/Sql/dbo/Stored Procedures/User_UpdateStorage.sql b/src/Sql/dbo/Stored Procedures/User_UpdateStorage.sql index bcc117122e..9d59c750fb 100644 --- a/src/Sql/dbo/Stored Procedures/User_UpdateStorage.sql +++ b/src/Sql/dbo/Stored Procedures/User_UpdateStorage.sql @@ -6,6 +6,21 @@ BEGIN DECLARE @Storage BIGINT + CREATE TABLE #Temp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #Temp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] = @Id + ;WITH [CTE] AS ( SELECT [Id], @@ -16,16 +31,14 @@ BEGIN OPENJSON([Attachments]) ) [Size] FROM - [dbo].[Cipher] + #Temp ) SELECT @Storage = SUM([CTE].[Size]) FROM - [dbo].[Cipher] C - LEFT JOIN - [CTE] ON C.[Id] = [CTE].[Id] - WHERE - C.[UserId] = @Id + [CTE] + + DROP TABLE #Temp UPDATE [dbo].[User] diff --git a/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql b/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql index 720d1cf70a..44eb12a45d 100644 --- a/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql +++ b/util/Setup/DbScripts/2018-06-11_00_WebVaultUpdates.sql @@ -47,3 +47,120 @@ BEGIN ) END GO + +IF OBJECT_ID('[dbo].[Organization_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[Organization_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + CREATE TABLE #Temp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #Temp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] IS NULL + AND [OrganizationId] = @Id + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + #Temp + ) + SELECT + @Storage = SUM([Size]) + FROM + [CTE] + + DROP TABLE #Temp + + UPDATE + [dbo].[Organization] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[User_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + CREATE TABLE #Temp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #Temp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] = @Id + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + #Temp + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [CTE] + + DROP TABLE #Temp + + UPDATE + [dbo].[User] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO