From 35804e10cfab823884bc39b495bd4131ef99b851 Mon Sep 17 00:00:00 2001 From: Kyle Spearrin Date: Tue, 28 May 2019 23:55:35 -0400 Subject: [PATCH] collection cipher query improvements --- .../CollectionCipher_UpdateCollections.sql | 11 +- ...ollectionCipher_UpdateCollectionsAdmin.sql | 11 +- ...-05-28_00_CollectionCipherImprovements.sql | 143 ++++++++++++++++++ 3 files changed, 163 insertions(+), 2 deletions(-) create mode 100644 util/Migrator/DbScripts/2019-05-28_00_CollectionCipherImprovements.sql diff --git a/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollections.sql b/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollections.sql index cdefe8b1c..61ca28f5d 100644 --- a/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollections.sql +++ b/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollections.sql @@ -42,9 +42,18 @@ BEGIN OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 ) + ), + [CollectionCiphersCTE] AS( + SELECT + [CollectionId], + [CipherId] + FROM + [dbo].[CollectionCipher] + WHERE + [CipherId] = @CipherId ) MERGE - [dbo].[CollectionCipher] AS [Target] + [CollectionCiphersCTE] AS [Target] USING @CollectionIds AS [Source] ON diff --git a/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollectionsAdmin.sql b/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollectionsAdmin.sql index b8d71db18..5f7b0215d 100644 --- a/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollectionsAdmin.sql +++ b/src/Sql/dbo/Stored Procedures/CollectionCipher_UpdateCollectionsAdmin.sql @@ -13,9 +13,18 @@ BEGIN [dbo].[Collection] WHERE OrganizationId = @OrganizationId + ), + [CollectionCiphersCTE] AS( + SELECT + [CollectionId], + [CipherId] + FROM + [dbo].[CollectionCipher] + WHERE + [CipherId] = @CipherId ) MERGE - [dbo].[CollectionCipher] AS [Target] + [CollectionCiphersCTE] AS [Target] USING @CollectionIds AS [Source] ON diff --git a/util/Migrator/DbScripts/2019-05-28_00_CollectionCipherImprovements.sql b/util/Migrator/DbScripts/2019-05-28_00_CollectionCipherImprovements.sql new file mode 100644 index 000000000..33d1c1e9f --- /dev/null +++ b/util/Migrator/DbScripts/2019-05-28_00_CollectionCipherImprovements.sql @@ -0,0 +1,143 @@ +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollectionsAdmin]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsAdmin] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsAdmin] + @CipherId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + Id + FROM + [dbo].[Collection] + WHERE + OrganizationId = @OrganizationId + ), + [CollectionCiphersCTE] AS( + SELECT + [CollectionId], + [CipherId] + FROM + [dbo].[CollectionCipher] + WHERE + [CipherId] = @CipherId + ) + MERGE + [CollectionCiphersCTE] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId THEN + DELETE + ; + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END +END +GO + +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollections] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollections] + @CipherId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Cipher] + WHERE + [Id] = @CipherId + ) + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[CollectionId] = C.[Id] AND CU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[GroupUser] GU ON CU.[CollectionId] IS NULL AND OU.[AccessAll] = 0 AND GU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[Group] G ON G.[Id] = GU.[GroupId] + LEFT JOIN + [dbo].[CollectionGroup] CG ON G.[AccessAll] = 0 AND CG.[CollectionId] = C.[Id] AND CG.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrgId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + ), + [CollectionCiphersCTE] AS( + SELECT + [CollectionId], + [CipherId] + FROM + [dbo].[CollectionCipher] + WHERE + [CipherId] = @CipherId + ) + MERGE + [CollectionCiphersCTE] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId + AND [Target].[CollectionId] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + DELETE + ; + + IF @OrgId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId + END +END +GO