diff --git a/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql index f27e4110ef..fed619aedf 100644 --- a/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql +++ b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql @@ -14,35 +14,56 @@ BEGIN [Id] = @CollectionId ) - ;WITH [AvailableUsersCTE] AS( - SELECT - Id - FROM - [dbo].[OrganizationUser] - WHERE - OrganizationId = @OrgId - ) - MERGE - [dbo].[CollectionUser] AS [Target] - USING - @Users AS [Source] - ON + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly] + FROM + [dbo].[CollectionUser] [Target] + INNER JOIN + @Users [Source] ON [Source].[Id] = [Target].[OrganizationUserId] + WHERE [Target].[CollectionId] = @CollectionId - AND [Target].[OrganizationUserId] = [Source].[Id] - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN - INSERT VALUES - ( - @CollectionId, - [Source].[Id], - [Source].[ReadOnly] + AND [Target].[ReadOnly] != [Source].[ReadOnly] + + -- Insert + INSERT INTO + [dbo].[CollectionUser] + SELECT + @CollectionId, + [Source].[Id], + [Source].[ReadOnly] + FROM + @Users [Source] + INNER JOIN + [dbo].[OrganizationUser] OU ON [Source].[Id] = OU.[Id] AND OU.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = @CollectionId + AND [OrganizationUserId] = [Source].[Id] + ) + + -- Delete + DELETE + CU + FROM + [dbo].[CollectionUser] CU + WHERE + CU.[CollectionId] = @CollectionId + AND NOT EXISTS ( + SELECT + 1 + FROM + @Users + WHERE + [Id] = CU.[OrganizationUserId] ) - WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN - UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] - WHEN NOT MATCHED BY SOURCE - AND [Target].[CollectionId] = @CollectionId THEN - DELETE - ; EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrgId END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/GroupUser_UpdateGroups.sql b/src/Sql/dbo/Stored Procedures/GroupUser_UpdateGroups.sql index c977708469..c417d0c4d8 100644 --- a/src/Sql/dbo/Stored Procedures/GroupUser_UpdateGroups.sql +++ b/src/Sql/dbo/Stored Procedures/GroupUser_UpdateGroups.sql @@ -14,33 +14,42 @@ BEGIN [Id] = @OrganizationUserId ) - ;WITH [AvailableGroupsCTE] AS( - SELECT - [Id] - FROM - [dbo].[Group] - WHERE - [OrganizationId] = @OrgId - ) - MERGE - [dbo].[GroupUser] AS [Target] - USING - @GroupIds AS [Source] - ON - [Target].[GroupId] = [Source].[Id] - AND [Target].[OrganizationUserId] = @OrganizationUserId - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT VALUES - ( - [Source].[Id], - @OrganizationUserId + -- Insert + INSERT INTO + [dbo].[GroupUser] + SELECT + [Source].[Id], + @OrganizationUserId + FROM + @GroupIds [Source] + INNER JOIN + [dbo].[Group] G ON G.[Id] = [Source].[Id] AND G.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[GroupUser] + WHERE + [OrganizationUserId] = @OrganizationUserId + AND [GroupId] = [Source].[Id] + ) + + -- Delete + DELETE + GU + FROM + [dbo].[GroupUser] GU + WHERE + GU.[OrganizationUserId] = @OrganizationUserId + AND NOT EXISTS ( + SELECT + 1 + FROM + @GroupIds + WHERE + [Id] = GU.[GroupId] ) - WHEN NOT MATCHED BY SOURCE - AND [Target].[OrganizationUserId] = @OrganizationUserId - AND [Target].[GroupId] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - DELETE - ; EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/GroupUser_UpdateUsers.sql b/src/Sql/dbo/Stored Procedures/GroupUser_UpdateUsers.sql index 1e41def02d..750d3fe9ce 100644 --- a/src/Sql/dbo/Stored Procedures/GroupUser_UpdateUsers.sql +++ b/src/Sql/dbo/Stored Procedures/GroupUser_UpdateUsers.sql @@ -14,33 +14,42 @@ BEGIN [Id] = @GroupId ) - ;WITH [AvailableUsersCTE] AS( - SELECT - [Id] - FROM - [dbo].[OrganizationUser] - WHERE - [OrganizationId] = @OrgId - ) - MERGE - [dbo].[GroupUser] AS [Target] - USING + -- Insert + INSERT INTO + [dbo].[GroupUser] + SELECT + @GroupId, + [Source].[Id] + FROM @OrganizationUserIds AS [Source] - ON - [Target].[GroupId] = @GroupId - AND [Target].[OrganizationUserId] = [Source].[Id] - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN - INSERT VALUES - ( - @GroupId, - [Source].[Id] + INNER JOIN + [dbo].[OrganizationUser] OU ON [Source].[Id] = OU.[Id] AND OU.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[GroupUser] + WHERE + [GroupId] = @GroupId + AND [OrganizationUserId] = [Source].[Id] + ) + + -- Delete + DELETE + GU + FROM + [dbo].[GroupUser] GU + WHERE + GU.[GroupId] = @GroupId + AND NOT EXISTS ( + SELECT + 1 + FROM + @OrganizationUserIds + WHERE + [Id] = GU.[OrganizationUserId] ) - WHEN NOT MATCHED BY SOURCE - AND [Target].[GroupId] = @GroupId - AND [Target].[OrganizationUserId] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN - DELETE - ; EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql index b35d688775..d351752fb2 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql @@ -17,33 +17,54 @@ BEGIN EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate - ;WITH [AvailableCollectionsCTE] AS( - SELECT - Id - FROM - [dbo].[Collection] - WHERE - OrganizationId = @OrganizationId - ) - MERGE + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly] + FROM [dbo].[CollectionUser] AS [Target] - USING + INNER JOIN + @Collections AS [Source] ON [Source].[Id] = [Target].[CollectionId] + WHERE + [Target].[OrganizationUserId] = @Id + AND [Target].[ReadOnly] != [Source].[ReadOnly] + + -- Insert + INSERT INTO + [dbo].[CollectionUser] + SELECT + [Source].[Id], + @Id, + [Source].[ReadOnly] + FROM @Collections AS [Source] - ON - [Target].[CollectionId] = [Source].[Id] - AND [Target].[OrganizationUserId] = @Id - WHEN NOT MATCHED BY TARGET - AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN - INSERT VALUES - ( - [Source].[Id], - @Id, - [Source].[ReadOnly] + INNER JOIN + [dbo].[Collection] C ON C.[Id] = [Source].[Id] AND C.[OrganizationId] = @OrganizationId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = [Source].[Id] + AND [OrganizationUserId] = @Id + ) + + -- Delete + DELETE + CU + FROM + [dbo].[CollectionUser] CU + WHERE + CU.[OrganizationUserId] = @Id + AND NOT EXISTS ( + SELECT + 1 + FROM + @Collections + WHERE + [Id] = CU.[CollectionId] ) - WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN - UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] - WHEN NOT MATCHED BY SOURCE - AND [Target].[OrganizationUserId] = @Id THEN - DELETE - ; END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCipherId.sql b/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCipherId.sql index 53a12ed6e0..5b96db54a9 100644 --- a/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCipherId.sql +++ b/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCipherId.sql @@ -11,7 +11,7 @@ BEGIN U.[AccountRevisionDate] = GETUTCDATE() FROM [dbo].[User] U - LEFT JOIN + INNER JOIN [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] LEFT JOIN [dbo].[CollectionCipher] CC ON CC.[CipherId] = @CipherId @@ -24,16 +24,12 @@ BEGIN LEFT JOIN [dbo].[CollectionGroup] CG ON G.[AccessAll] = 0 AND CG.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = CC.[CollectionId] WHERE - OU.[Status] = 2 -- 2 = Confirmed + OU.[OrganizationId] = @OrganizationId + AND OU.[Status] = 2 -- 2 = Confirmed AND ( CU.[CollectionId] IS NOT NULL OR CG.[CollectionId] IS NOT NULL - OR ( - OU.[OrganizationId] = @OrganizationId - AND ( - OU.[AccessAll] = 1 - OR G.[AccessAll] = 1 - ) - ) + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 ) END diff --git a/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCollectionId.sql b/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCollectionId.sql index 0300fd2c8a..f001a54cdb 100644 --- a/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCollectionId.sql +++ b/src/Sql/dbo/Stored Procedures/User_BumpAccountRevisionDateByCollectionId.sql @@ -11,7 +11,7 @@ BEGIN U.[AccountRevisionDate] = GETUTCDATE() FROM [dbo].[User] U - LEFT JOIN + INNER JOIN [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] LEFT JOIN [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId @@ -22,16 +22,12 @@ BEGIN LEFT JOIN [dbo].[CollectionGroup] CG ON G.[AccessAll] = 0 AND CG.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId WHERE - OU.[Status] = 2 -- 2 = Confirmed + OU.[OrganizationId] = @OrganizationId + AND OU.[Status] = 2 -- 2 = Confirmed AND ( CU.[CollectionId] IS NOT NULL OR CG.[CollectionId] IS NOT NULL - OR ( - OU.[OrganizationId] = @OrganizationId - AND ( - OU.[AccessAll] = 1 - OR G.[AccessAll] = 1 - ) - ) + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 ) END diff --git a/util/Migrator/DbScripts/2020-05-02_00_SprocPerfTweaks.sql b/util/Migrator/DbScripts/2020-05-02_00_SprocPerfTweaks.sql new file mode 100644 index 0000000000..a0f662bbf2 --- /dev/null +++ b/util/Migrator/DbScripts/2020-05-02_00_SprocPerfTweaks.sql @@ -0,0 +1,368 @@ +/** + * Performance updates to various sprocs + */ + +IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers]; +END +GO + +CREATE PROCEDURE [dbo].[CollectionUser_UpdateUsers] + @CollectionId UNIQUEIDENTIFIER, + @Users AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Collection] + WHERE + [Id] = @CollectionId + ) + + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly] + FROM + [dbo].[CollectionUser] [Target] + INNER JOIN + @Users [Source] ON [Source].[Id] = [Target].[OrganizationUserId] + WHERE + [Target].[CollectionId] = @CollectionId + AND [Target].[ReadOnly] != [Source].[ReadOnly] + + -- Insert + INSERT INTO + [dbo].[CollectionUser] + SELECT + @CollectionId, + [Source].[Id], + [Source].[ReadOnly] + FROM + @Users [Source] + INNER JOIN + [dbo].[OrganizationUser] OU ON [Source].[Id] = OU.[Id] AND OU.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = @CollectionId + AND [OrganizationUserId] = [Source].[Id] + ) + + -- Delete + DELETE + CU + FROM + [dbo].[CollectionUser] CU + WHERE + CU.[CollectionId] = @CollectionId + AND NOT EXISTS ( + SELECT + 1 + FROM + @Users + WHERE + [Id] = CU.[OrganizationUserId] + ) + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrgId +END +GO + +IF OBJECT_ID('[dbo].[GroupUser_UpdateGroups]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[GroupUser_UpdateGroups]; +END +GO + +CREATE PROCEDURE [dbo].[GroupUser_UpdateGroups] + @OrganizationUserId UNIQUEIDENTIFIER, + @GroupIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[OrganizationUser] + WHERE + [Id] = @OrganizationUserId + ) + + -- Insert + INSERT INTO + [dbo].[GroupUser] + SELECT + [Source].[Id], + @OrganizationUserId + FROM + @GroupIds [Source] + INNER JOIN + [dbo].[Group] G ON G.[Id] = [Source].[Id] AND G.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[GroupUser] + WHERE + [OrganizationUserId] = @OrganizationUserId + AND [GroupId] = [Source].[Id] + ) + + -- Delete + DELETE + GU + FROM + [dbo].[GroupUser] GU + WHERE + GU.[OrganizationUserId] = @OrganizationUserId + AND NOT EXISTS ( + SELECT + 1 + FROM + @GroupIds + WHERE + [Id] = GU.[GroupId] + ) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId +END +GO + +IF OBJECT_ID('[dbo].[GroupUser_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[GroupUser_UpdateUsers]; +END +GO + +CREATE PROCEDURE [dbo].[GroupUser_UpdateUsers] + @GroupId UNIQUEIDENTIFIER, + @OrganizationUserIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Group] + WHERE + [Id] = @GroupId + ) + + -- Insert + INSERT INTO + [dbo].[GroupUser] + SELECT + @GroupId, + [Source].[Id] + FROM + @OrganizationUserIds AS [Source] + INNER JOIN + [dbo].[OrganizationUser] OU ON [Source].[Id] = OU.[Id] AND OU.[OrganizationId] = @OrgId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[GroupUser] + WHERE + [GroupId] = @GroupId + AND [OrganizationUserId] = [Source].[Id] + ) + + -- Delete + DELETE + GU + FROM + [dbo].[GroupUser] GU + WHERE + GU.[GroupId] = @GroupId + AND NOT EXISTS ( + SELECT + 1 + FROM + @OrganizationUserIds + WHERE + [Id] = GU.[OrganizationUserId] + ) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections]; +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(MAX), + @Status TINYINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly] + FROM + [dbo].[CollectionUser] AS [Target] + INNER JOIN + @Collections AS [Source] ON [Source].[Id] = [Target].[CollectionId] + WHERE + [Target].[OrganizationUserId] = @Id + AND [Target].[ReadOnly] != [Source].[ReadOnly] + + -- Insert + INSERT INTO + [dbo].[CollectionUser] + SELECT + [Source].[Id], + @Id, + [Source].[ReadOnly] + FROM + @Collections AS [Source] + INNER JOIN + [dbo].[Collection] C ON C.[Id] = [Source].[Id] AND C.[OrganizationId] = @OrganizationId + WHERE + NOT EXISTS ( + SELECT + 1 + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = [Source].[Id] + AND [OrganizationUserId] = @Id + ) + + -- Delete + DELETE + CU + FROM + [dbo].[CollectionUser] CU + WHERE + CU.[OrganizationUserId] = @Id + AND NOT EXISTS ( + SELECT + 1 + FROM + @Collections + WHERE + [Id] = CU.[CollectionId] + ) +END +GO + +IF OBJECT_ID('[dbo].[User_BumpAccountRevisionDateByCipherId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_BumpAccountRevisionDateByCipherId]; +END +GO + +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByCipherId] + @CipherId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + LEFT JOIN + [dbo].[CollectionCipher] CC ON CC.[CipherId] = @CipherId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = CC.[CollectionId] + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = CC.[CollectionId] + WHERE + OU.[OrganizationId] = @OrganizationId + AND OU.[Status] = 2 -- 2 = Confirmed + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) +END +GO + +IF OBJECT_ID('[dbo].[User_BumpAccountRevisionDateByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_BumpAccountRevisionDateByCollectionId]; +END +GO + +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByCollectionId] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId + WHERE + OU.[OrganizationId] = @OrganizationId + AND OU.[Status] = 2 -- 2 = Confirmed + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) +END +GO