From 3a5c35b5565c6f43e3dab2479ebdf9ede6d95c30 Mon Sep 17 00:00:00 2001 From: Shane Melton Date: Mon, 23 Oct 2023 18:46:14 -0700 Subject: [PATCH] [AC-1683] Fix DB migrations for new Manage permission (#3307) * [AC-1683] Update migration script and introduce V2 procedures and types * [AC-1683] Update repository calls to use new V2 procedures / types * [AC-1684] Update bulk add collection migration script to use new V2 type * [AC-1683] Undo Manage changes to more original procedures * [AC-1683] Restore whitespace changes * [AC-1683] Clarify comments regarding explicit column lists * [AC-1683] Update migration script dates * [AC-1683] Split the migration script for readability * [AC-1683] Re-name SelectReadOnlyArray_V2 to CollectionAccessSelectionType --- .../Repositories/GroupRepository.cs | 4 +- src/Infrastructure.Dapper/DapperHelpers.cs | 2 +- .../Repositories/CollectionRepository.cs | 6 +- .../OrganizationUserRepository.cs | 4 +- .../CollectionUser_UpdateUsers.sql | 20 +- .../CollectionUser_UpdateUsers_V2.sql | 83 +++ ...Collection_CreateOrUpdateAccessForMany.sql | 24 +- .../Collection_CreateWithGroupsAndUsers.sql | 14 +- ...Collection_CreateWithGroupsAndUsers_V2.sql | 73 ++ .../Collection_UpdateWithGroupsAndUsers.sql | 36 +- ...Collection_UpdateWithGroupsAndUsers_V2.sql | 111 +++ .../Group_CreateWithCollections.sql | 8 +- .../Group_CreateWithCollections_V2.sql | 44 ++ .../Group_UpdateWithCollections.sql | 18 +- .../Group_UpdateWithCollections_V2.sql | 63 ++ ...OrganizationUser_CreateWithCollections.sql | 6 +- ...anizationUser_CreateWithCollections_V2.sql | 49 ++ ...OrganizationUser_UpdateWithCollections.sql | 18 +- ...anizationUser_UpdateWithCollections_V2.sql | 86 +++ .../CollectionAccessSelection.sql | 6 + .../SelectionReadOnlyArray.sql | 3 +- ...23-10-17_00_CollectionManagePermission.sql | 340 +++++++++ ...3-10-17_01_CollectionManagePermission.sql} | 699 ++++++++++-------- ...2023-10-17_02_BulkAddCollectionAccess.sql} | 24 +- .../2023-10-FutureMigrations.sql | 50 ++ 25 files changed, 1393 insertions(+), 398 deletions(-) create mode 100644 src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/Group_CreateWithCollections_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections_V2.sql create mode 100644 src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections_V2.sql create mode 100644 src/Sql/dbo/User Defined Types/CollectionAccessSelection.sql create mode 100644 util/Migrator/DbScripts/2023-10-17_00_CollectionManagePermission.sql rename util/Migrator/DbScripts/{2023-07-11_00_CollectionManagePermission.sql => 2023-10-17_01_CollectionManagePermission.sql} (78%) rename util/Migrator/DbScripts/{2023-08-25_00_BulkAddCollectionAccess.sql => 2023-10-17_02_BulkAddCollectionAccess.sql} (89%) create mode 100644 util/Migrator/DbScripts_finalization/2023-10-FutureMigrations.sql diff --git a/src/Infrastructure.Dapper/AdminConsole/Repositories/GroupRepository.cs b/src/Infrastructure.Dapper/AdminConsole/Repositories/GroupRepository.cs index 13c0bc5bf1..5230080626 100644 --- a/src/Infrastructure.Dapper/AdminConsole/Repositories/GroupRepository.cs +++ b/src/Infrastructure.Dapper/AdminConsole/Repositories/GroupRepository.cs @@ -142,7 +142,7 @@ public class GroupRepository : Repository, IGroupRepository using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[Group_CreateWithCollections]", + $"[{Schema}].[Group_CreateWithCollections_V2]", objWithCollections, commandType: CommandType.StoredProcedure); } @@ -156,7 +156,7 @@ public class GroupRepository : Repository, IGroupRepository using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[Group_UpdateWithCollections]", + $"[{Schema}].[Group_UpdateWithCollections_V2]", objWithCollections, commandType: CommandType.StoredProcedure); } diff --git a/src/Infrastructure.Dapper/DapperHelpers.cs b/src/Infrastructure.Dapper/DapperHelpers.cs index c14dfb5d46..b5e4dc6e5d 100644 --- a/src/Infrastructure.Dapper/DapperHelpers.cs +++ b/src/Infrastructure.Dapper/DapperHelpers.cs @@ -32,7 +32,7 @@ public static class DapperHelpers public static DataTable ToArrayTVP(this IEnumerable values) { var table = new DataTable(); - table.SetTypeName("[dbo].[SelectionReadOnlyArray]"); + table.SetTypeName("[dbo].[CollectionAccessSelectionType]"); var idColumn = new DataColumn("Id", typeof(Guid)); table.Columns.Add(idColumn); diff --git a/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs b/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs index 37949da464..b9b0deefb6 100644 --- a/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs +++ b/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs @@ -221,7 +221,7 @@ public class CollectionRepository : Repository, ICollectionRep using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[Collection_CreateWithGroupsAndUsers]", + $"[{Schema}].[Collection_CreateWithGroupsAndUsers_V2]", objWithGroupsAndUsers, commandType: CommandType.StoredProcedure); } @@ -237,7 +237,7 @@ public class CollectionRepository : Repository, ICollectionRep using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[Collection_UpdateWithGroupsAndUsers]", + $"[{Schema}].[Collection_UpdateWithGroupsAndUsers_V2]", objWithGroupsAndUsers, commandType: CommandType.StoredProcedure); } @@ -294,7 +294,7 @@ public class CollectionRepository : Repository, ICollectionRep using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[CollectionUser_UpdateUsers]", + $"[{Schema}].[CollectionUser_UpdateUsers_V2]", new { CollectionId = id, Users = users.ToArrayTVP() }, commandType: CommandType.StoredProcedure); } diff --git a/src/Infrastructure.Dapper/Repositories/OrganizationUserRepository.cs b/src/Infrastructure.Dapper/Repositories/OrganizationUserRepository.cs index 4f0eb70cb0..2a2f0e340a 100644 --- a/src/Infrastructure.Dapper/Repositories/OrganizationUserRepository.cs +++ b/src/Infrastructure.Dapper/Repositories/OrganizationUserRepository.cs @@ -326,7 +326,7 @@ public class OrganizationUserRepository : Repository, IO using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[OrganizationUser_CreateWithCollections]", + $"[{Schema}].[OrganizationUser_CreateWithCollections_V2]", objWithCollections, commandType: CommandType.StoredProcedure); } @@ -343,7 +343,7 @@ public class OrganizationUserRepository : Repository, IO using (var connection = new SqlConnection(ConnectionString)) { var results = await connection.ExecuteAsync( - $"[{Schema}].[OrganizationUser_UpdateWithCollections]", + $"[{Schema}].[OrganizationUser_UpdateWithCollections_V2]", objWithCollections, commandType: CommandType.StoredProcedure); } diff --git a/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql index 9b8d3a10c0..eb59899e3d 100644 --- a/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql +++ b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers.sql @@ -19,8 +19,7 @@ BEGIN [Target] SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] + [Target].[HidePasswords] = [Source].[HidePasswords] FROM [dbo].[CollectionUser] [Target] INNER JOIN @@ -30,18 +29,21 @@ BEGIN AND ( [Target].[ReadOnly] != [Source].[ReadOnly] OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] ) - -- Insert - INSERT INTO - [dbo].[CollectionUser] + -- Insert (with column list because a value for Manage is not being provided) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) SELECT @CollectionId, [Source].[Id], [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] + [Source].[HidePasswords] FROM @Users [Source] INNER JOIN @@ -56,7 +58,7 @@ BEGIN [CollectionId] = @CollectionId AND [OrganizationUserId] = [Source].[Id] ) - + -- Delete DELETE CU diff --git a/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers_V2.sql b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers_V2.sql new file mode 100644 index 0000000000..c7a68b0d1f --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/CollectionUser_UpdateUsers_V2.sql @@ -0,0 +1,83 @@ +CREATE PROCEDURE [dbo].[CollectionUser_UpdateUsers_V2] + @CollectionId UNIQUEIDENTIFIER, + @Users AS [dbo].[CollectionAccessSelectionType] 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], + [Target].[HidePasswords] = [Source].[HidePasswords], + [Target].[Manage] = [Source].[Manage] + FROM + [dbo].[CollectionUser] [Target] + INNER JOIN + @Users [Source] ON [Source].[Id] = [Target].[OrganizationUserId] + WHERE + [Target].[CollectionId] = @CollectionId + AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + OR [Target].[Manage] != [Source].[Manage] + ) + + -- Insert + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + @CollectionId, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords], + [Source].[Manage] + 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 diff --git a/src/Sql/dbo/Stored Procedures/Collection_CreateOrUpdateAccessForMany.sql b/src/Sql/dbo/Stored Procedures/Collection_CreateOrUpdateAccessForMany.sql index e7f860fa60..6a41971aa0 100644 --- a/src/Sql/dbo/Stored Procedures/Collection_CreateOrUpdateAccessForMany.sql +++ b/src/Sql/dbo/Stored Procedures/Collection_CreateOrUpdateAccessForMany.sql @@ -1,8 +1,8 @@ CREATE PROCEDURE [dbo].[Collection_CreateOrUpdateAccessForMany] @OrganizationId UNIQUEIDENTIFIER, @CollectionIds AS [dbo].[GuidIdArray] READONLY, - @Groups AS [dbo].[SelectionReadOnlyArray] READONLY, - @Users AS [dbo].[SelectionReadOnlyArray] READONLY + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -41,7 +41,15 @@ BEGIN [Target].[HidePasswords] = [Source].[HidePasswords], [Target].[Manage] = [Source].[Manage] WHEN NOT MATCHED BY TARGET - THEN INSERT VALUES + THEN INSERT + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( [Source].[CollectionId], [Source].[GroupId], @@ -84,7 +92,15 @@ BEGIN [Target].[HidePasswords] = [Source].[HidePasswords], [Target].[Manage] = [Source].[Manage] WHEN NOT MATCHED BY TARGET - THEN INSERT VALUES + THEN INSERT + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( [Source].[CollectionId], [Source].[OrganizationUserId], diff --git a/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers.sql b/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers.sql index 0087e9605c..120a5e83dd 100644 --- a/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers.sql +++ b/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers.sql @@ -27,15 +27,13 @@ BEGIN [CollectionId], [GroupId], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] ) SELECT @Id, [Id], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] FROM @Groups WHERE @@ -55,19 +53,17 @@ BEGIN [CollectionId], [OrganizationUserId], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] ) SELECT @Id, [Id], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] FROM @Users WHERE [Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId -END +END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers_V2.sql b/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers_V2.sql new file mode 100644 index 0000000000..11e2cdc070 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Collection_CreateWithGroupsAndUsers_V2.sql @@ -0,0 +1,73 @@ +CREATE PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Create] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + -- Groups + ;WITH [AvailableGroupsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Group] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + @Id, + [Id], + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Groups + WHERE + [Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) + + -- Users + ;WITH [AvailableUsersCTE] AS( + SELECT + [Id] + FROM + [dbo].[OrganizationUser] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + @Id, + [Id], + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Users + WHERE + [Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END diff --git a/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql index 74328a1983..42ed69e36e 100644 --- a/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql +++ b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers.sql @@ -24,29 +24,33 @@ BEGIN ) MERGE [dbo].[CollectionGroup] AS [Target] - USING + USING @Groups AS [Source] ON [Target].[CollectionId] = @Id AND [Target].[GroupId] = [Source].[Id] WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT VALUES + INSERT -- With column list because a value for Manage is not being provided + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords] + ) + VALUES ( @Id, [Source].[Id], [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] + [Source].[HidePasswords] ) WHEN MATCHED AND ( [Target].[ReadOnly] != [Source].[ReadOnly] OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] ) THEN UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] + [Target].[HidePasswords] = [Source].[HidePasswords] WHEN NOT MATCHED BY SOURCE AND [Target].[CollectionId] = @Id THEN DELETE @@ -63,29 +67,33 @@ BEGIN ) MERGE [dbo].[CollectionUser] AS [Target] - USING + USING @Users AS [Source] ON [Target].[CollectionId] = @Id AND [Target].[OrganizationUserId] = [Source].[Id] WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT VALUES + INSERT -- With column list because a value for Manage is not being provided + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) + VALUES ( @Id, [Source].[Id], [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] + [Source].[HidePasswords] ) WHEN MATCHED AND ( [Target].[ReadOnly] != [Source].[ReadOnly] OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] ) THEN UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] + [Target].[HidePasswords] = [Source].[HidePasswords] WHEN NOT MATCHED BY SOURCE AND [Target].[CollectionId] = @Id THEN DELETE diff --git a/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers_V2.sql b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers_V2.sql new file mode 100644 index 0000000000..1f9cff8fd8 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Collection_UpdateWithGroupsAndUsers_V2.sql @@ -0,0 +1,111 @@ +CREATE PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + -- Groups + ;WITH [AvailableGroupsCTE] AS( + SELECT + Id + FROM + [dbo].[Group] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionGroup] AS [Target] + USING + @Groups AS [Source] + ON + [Target].[CollectionId] = @Id + AND [Target].[GroupId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + INSERT -- Add explicit column list + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords], + [Source].[Manage] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + OR [Target].[Manage] != [Source].[Manage] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords], + [Target].[Manage] = [Source].[Manage] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + -- Users + ;WITH [AvailableGroupsCTE] AS( + SELECT + Id + FROM + [dbo].[OrganizationUser] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionUser] AS [Target] + USING + @Users AS [Source] + ON + [Target].[CollectionId] = @Id + AND [Target].[OrganizationUserId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + INSERT + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords], + [Source].[Manage] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + OR [Target].[Manage] != [Source].[Manage] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords], + [Target].[Manage] = [Source].[Manage] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END diff --git a/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections.sql b/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections.sql index 2538675847..b41637522e 100644 --- a/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections.sql +++ b/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections.sql @@ -26,19 +26,17 @@ BEGIN [CollectionId], [GroupId], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] ) SELECT [Id], @Id, [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] FROM @Collections WHERE [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId -END +END \ No newline at end of file diff --git a/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections_V2.sql b/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections_V2.sql new file mode 100644 index 0000000000..66c98996f5 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Group_CreateWithCollections_V2.sql @@ -0,0 +1,44 @@ +CREATE PROCEDURE [dbo].[Group_CreateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name NVARCHAR(100), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_Create] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + [Id], + @Id, + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END diff --git a/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections.sql b/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections.sql index 997476c685..86ec4342cf 100644 --- a/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections.sql +++ b/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections.sql @@ -23,29 +23,33 @@ BEGIN ) MERGE [dbo].[CollectionGroup] AS [Target] - USING + USING @Collections AS [Source] ON [Target].[CollectionId] = [Source].[Id] AND [Target].[GroupId] = @Id WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN - INSERT VALUES + INSERT -- With column list because a value for Manage is not being provided + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords] + ) + VALUES ( [Source].[Id], @Id, [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] + [Source].[HidePasswords] ) WHEN MATCHED AND ( [Target].[ReadOnly] != [Source].[ReadOnly] OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] ) THEN UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] + [Target].[HidePasswords] = [Source].[HidePasswords] WHEN NOT MATCHED BY SOURCE AND [Target].[GroupId] = @Id THEN DELETE diff --git a/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections_V2.sql b/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections_V2.sql new file mode 100644 index 0000000000..40f22a9687 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/Group_UpdateWithCollections_V2.sql @@ -0,0 +1,63 @@ +CREATE PROCEDURE [dbo].[Group_UpdateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name NVARCHAR(100), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_Update] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + Id + FROM + [dbo].[Collection] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionGroup] AS [Target] + USING + @Collections AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[GroupId] = @Id + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES + ( + [Source].[Id], + @Id, + [Source].[ReadOnly], + [Source].[HidePasswords], + [Source].[Manage] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + OR [Target].[Manage] != [Source].[Manage] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords], + [Target].[Manage] = [Source].[Manage] + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections.sql index e1a67d645d..98809a0ec2 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections.sql @@ -33,15 +33,13 @@ BEGIN [CollectionId], [OrganizationUserId], [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] ) SELECT [Id], @Id, [ReadOnly], - [HidePasswords], - [Manage] + [HidePasswords] FROM @Collections WHERE diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections_V2.sql new file mode 100644 index 0000000000..50b1fb5fc5 --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_CreateWithCollections_V2.sql @@ -0,0 +1,49 @@ +CREATE PROCEDURE [dbo].[OrganizationUser_CreateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(256), + @Key VARCHAR(MAX), + @Status SMALLINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Permissions NVARCHAR(MAX), + @ResetPasswordKey VARCHAR(MAX), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY, + @AccessSecretsManager BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Create] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + [Id], + @Id, + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) +END diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql index 96272867db..0a9ff4f034 100644 --- a/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections.sql @@ -24,8 +24,7 @@ BEGIN [Target] SET [Target].[ReadOnly] = [Source].[ReadOnly], - [Target].[HidePasswords] = [Source].[HidePasswords], - [Target].[Manage] = [Source].[Manage] + [Target].[HidePasswords] = [Source].[HidePasswords] FROM [dbo].[CollectionUser] AS [Target] INNER JOIN @@ -35,18 +34,21 @@ BEGIN AND ( [Target].[ReadOnly] != [Source].[ReadOnly] OR [Target].[HidePasswords] != [Source].[HidePasswords] - OR [Target].[Manage] != [Source].[Manage] ) - -- Insert - INSERT INTO - [dbo].[CollectionUser] + -- Insert (with column list because a value for Manage is not being provided) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) SELECT [Source].[Id], @Id, [Source].[ReadOnly], - [Source].[HidePasswords], - [Source].[Manage] + [Source].[HidePasswords] FROM @Collections AS [Source] INNER JOIN diff --git a/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections_V2.sql b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections_V2.sql new file mode 100644 index 0000000000..f152df3b1e --- /dev/null +++ b/src/Sql/dbo/Stored Procedures/OrganizationUser_UpdateWithCollections_V2.sql @@ -0,0 +1,86 @@ +CREATE PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(256), + @Key VARCHAR(MAX), + @Status SMALLINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Permissions NVARCHAR(MAX), + @ResetPasswordKey VARCHAR(MAX), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY, + @AccessSecretsManager BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords], + [Target].[Manage] = [Source].[Manage] + FROM + [dbo].[CollectionUser] AS [Target] + INNER JOIN + @Collections AS [Source] ON [Source].[Id] = [Target].[CollectionId] + WHERE + [Target].[OrganizationUserId] = @Id + AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + OR [Target].[Manage] != [Source].[Manage] + ) + + -- Insert + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + [Source].[Id], + @Id, + [Source].[ReadOnly], + [Source].[HidePasswords], + [Source].[Manage] + 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 diff --git a/src/Sql/dbo/User Defined Types/CollectionAccessSelection.sql b/src/Sql/dbo/User Defined Types/CollectionAccessSelection.sql new file mode 100644 index 0000000000..07bb178464 --- /dev/null +++ b/src/Sql/dbo/User Defined Types/CollectionAccessSelection.sql @@ -0,0 +1,6 @@ +CREATE TYPE [dbo].[CollectionAccessSelectionType] AS TABLE ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [ReadOnly] BIT NOT NULL, + [HidePasswords] BIT NOT NULL, + [Manage] BIT NOT NULL); + diff --git a/src/Sql/dbo/User Defined Types/SelectionReadOnlyArray.sql b/src/Sql/dbo/User Defined Types/SelectionReadOnlyArray.sql index 319ec8c1c4..f2e19b1a09 100644 --- a/src/Sql/dbo/User Defined Types/SelectionReadOnlyArray.sql +++ b/src/Sql/dbo/User Defined Types/SelectionReadOnlyArray.sql @@ -1,6 +1,5 @@ CREATE TYPE [dbo].[SelectionReadOnlyArray] AS TABLE ( [Id] UNIQUEIDENTIFIER NOT NULL, [ReadOnly] BIT NOT NULL, - [HidePasswords] BIT NOT NULL, - [Manage] BIT NOT NULL); + [HidePasswords] BIT NOT NULL); diff --git a/util/Migrator/DbScripts/2023-10-17_00_CollectionManagePermission.sql b/util/Migrator/DbScripts/2023-10-17_00_CollectionManagePermission.sql new file mode 100644 index 0000000000..7341e70976 --- /dev/null +++ b/util/Migrator/DbScripts/2023-10-17_00_CollectionManagePermission.sql @@ -0,0 +1,340 @@ +/* + * Update existing write procedures to safely ignore any newly added columns to the CollectionUser and + * CollectionGroup tables (e.g. preparation for [Manage] in the next migration script). This is accomplished by + * explicitly listing the columns in the INSERT and UPDATE statements. + */ + +-- Update INSERT statement to include explicit column list +CREATE OR ALTER 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], + [Target].[HidePasswords] = [Source].[HidePasswords] + FROM + [dbo].[CollectionUser] [Target] + INNER JOIN + @Users [Source] ON [Source].[Id] = [Target].[OrganizationUserId] + WHERE + [Target].[CollectionId] = @CollectionId + AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + ) + + -- Insert + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) + SELECT + @CollectionId, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords] + 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 + +-- Update INSERT statement to include explicit column list +CREATE OR ALTER PROCEDURE [dbo].[Group_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name NVARCHAR(100), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_Update] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + Id + FROM + [dbo].[Collection] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionGroup] AS [Target] + USING + @Collections AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[GroupId] = @Id + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords] + ) + VALUES + ( + [Source].[Id], + @Id, + [Source].[ReadOnly], + [Source].[HidePasswords] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords] + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +-- Update INSERT statements to include explicit column list +CREATE OR ALTER PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY, + @Users AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + -- Groups + ;WITH [AvailableGroupsCTE] AS( + SELECT + Id + FROM + [dbo].[Group] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionGroup] AS [Target] + USING + @Groups AS [Source] + ON + [Target].[CollectionId] = @Id + AND [Target].[GroupId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + INSERT -- With column list because a value for Manage is not being provided + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords] + ) + VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + -- Users + ;WITH [AvailableGroupsCTE] AS( + SELECT + Id + FROM + [dbo].[OrganizationUser] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionUser] AS [Target] + USING + @Users AS [Source] + ON + [Target].[CollectionId] = @Id + AND [Target].[OrganizationUserId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + INSERT + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) + VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly], + [Source].[HidePasswords] + ) + WHEN MATCHED AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + ) THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +-- Update INSERT statement to include explicit column list +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(256), + @Key VARCHAR(MAX), + @Status SMALLINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Permissions NVARCHAR(MAX), + @ResetPasswordKey VARCHAR(MAX), + @Collections AS [dbo].[SelectionReadOnlyArray] READONLY, + @AccessSecretsManager BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager + -- Update + UPDATE + [Target] + SET + [Target].[ReadOnly] = [Source].[ReadOnly], + [Target].[HidePasswords] = [Source].[HidePasswords] + FROM + [dbo].[CollectionUser] AS [Target] + INNER JOIN + @Collections AS [Source] ON [Source].[Id] = [Target].[CollectionId] + WHERE + [Target].[OrganizationUserId] = @Id + AND ( + [Target].[ReadOnly] != [Source].[ReadOnly] + OR [Target].[HidePasswords] != [Source].[HidePasswords] + ) + + -- Insert + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords] + ) + SELECT + [Source].[Id], + @Id, + [Source].[ReadOnly], + [Source].[HidePasswords] + 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 diff --git a/util/Migrator/DbScripts/2023-07-11_00_CollectionManagePermission.sql b/util/Migrator/DbScripts/2023-10-17_01_CollectionManagePermission.sql similarity index 78% rename from util/Migrator/DbScripts/2023-07-11_00_CollectionManagePermission.sql rename to util/Migrator/DbScripts/2023-10-17_01_CollectionManagePermission.sql index 50e4c7d96c..2d6f45bf3f 100644 --- a/util/Migrator/DbScripts/2023-07-11_00_CollectionManagePermission.sql +++ b/util/Migrator/DbScripts/2023-10-17_01_CollectionManagePermission.sql @@ -1,79 +1,83 @@ /* - * Add Manage permission to collections + * Add Manage permission to collections and update associated stored procedures */ --- Drop procedures that use the SelectionReadOnlyArray type -IF OBJECT_ID('[dbo].[Group_CreateWithCollections]') IS NOT NULL +-- To allow the migration to be re-run, drop any of the V2 procedures as they depend on a new type + +IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[Group_CreateWithCollections] + DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers_V2] END GO -IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers]') IS NOT NULL +IF OBJECT_ID('[dbo].[Group_UpdateWithCollections_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers] + DROP PROCEDURE [dbo].[Group_UpdateWithCollections_V2] END GO -IF OBJECT_ID('[dbo].[Group_UpdateWithCollections]') IS NOT NULL +IF OBJECT_ID('[dbo].[Collection_UpdateWithGroupsAndUsers_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[Group_UpdateWithCollections] + DROP PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers_V2] END GO -IF OBJECT_ID('[dbo].[Collection_UpdateWithGroupsAndUsers]') IS NOT NULL +IF OBJECT_ID('[dbo].[OrganizationUser_UpdateWithCollections_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers] + DROP PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections_V2] END GO -IF OBJECT_ID('[dbo].[OrganizationUser_CreateWithCollections]') IS NOT NULL +IF OBJECT_ID('[dbo].[Group_CreateWithCollections_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[OrganizationUser_CreateWithCollections] + DROP PROCEDURE [dbo].[Group_CreateWithCollections_V2] END GO -IF OBJECT_ID('[dbo].[OrganizationUser_UpdateWithCollections]') IS NOT NULL +IF OBJECT_ID('[dbo].[OrganizationUser_CreateWithCollections_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] + DROP PROCEDURE [dbo].[OrganizationUser_CreateWithCollections_V2] END GO -IF OBJECT_ID('[dbo].[Collection_CreateWithGroupsAndUsers]') IS NOT NULL +IF OBJECT_ID('[dbo].[Collection_CreateWithGroupsAndUsers_V2]') IS NOT NULL BEGIN - DROP PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers] + DROP PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers_V2] END GO -IF TYPE_ID('[dbo].[SelectionReadOnlyArray]') IS NOT NULL +-- Create a new CollectionAccessSelectionType with a new [Manage] column +IF TYPE_ID('[dbo].[CollectionAccessSelectionType]') IS NOT NULL BEGIN - DROP TYPE [dbo].[SelectionReadOnlyArray] + DROP TYPE [dbo].[CollectionAccessSelectionType] END GO -CREATE TYPE [dbo].[SelectionReadOnlyArray] AS TABLE ( +CREATE TYPE [dbo].[CollectionAccessSelectionType] AS TABLE ( [Id] UNIQUEIDENTIFIER NOT NULL, [ReadOnly] BIT NOT NULL, [HidePasswords] BIT NOT NULL, [Manage] BIT NOT NULL); GO - - ---Add Manage Column +-- Add Manage Column IF COL_LENGTH('[dbo].[CollectionUser]', 'Manage') IS NULL BEGIN ALTER TABLE [dbo].[CollectionUser] ADD [Manage] BIT NOT NULL CONSTRAINT D_CollectionUser_Manage DEFAULT (0); END GO ---Add Manage Column +-- Add Manage Column IF COL_LENGTH('[dbo].[CollectionGroup]', 'Manage') IS NULL BEGIN ALTER TABLE [dbo].[CollectionGroup] ADD [Manage] BIT NOT NULL CONSTRAINT D_CollectionGroup_Manage DEFAULT (0); END GO +-- BEGIN Update procedures that support backwards compatability in place +-- These procedures can be safely used by server in case of rollback and do not require V2 versions + +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server CREATE OR ALTER PROCEDURE [dbo].[CollectionUser_ReadByCollectionId] @CollectionId UNIQUEIDENTIFIER AS @@ -92,6 +96,7 @@ BEGIN END GO +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server CREATE OR ALTER PROCEDURE [dbo].[CollectionGroup_ReadByCollectionId] @CollectionId UNIQUEIDENTIFIER AS @@ -110,55 +115,215 @@ BEGIN END GO -CREATE PROCEDURE [dbo].[Group_CreateWithCollections] - @Id UNIQUEIDENTIFIER, - @OrganizationId UNIQUEIDENTIFIER, - @Name NVARCHAR(100), - @AccessAll BIT, - @ExternalId NVARCHAR(300), - @CreationDate DATETIME2(7), - @RevisionDate DATETIME2(7), - @Collections AS [dbo].[SelectionReadOnlyArray] READONLY +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadWithCollectionsById] + @Id UNIQUEIDENTIFIER AS BEGIN SET NOCOUNT ON - EXEC [dbo].[Group_Create] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + EXEC [OrganizationUserUserDetails_ReadById] @Id - ;WITH [AvailableCollectionsCTE] AS( - SELECT - [Id] - FROM - [dbo].[Collection] - WHERE - [OrganizationId] = @OrganizationId - ) - INSERT INTO [dbo].[CollectionGroup] - ( - [CollectionId], - [GroupId], - [ReadOnly], - [HidePasswords], - [Manage] +SELECT + CU.[CollectionId] Id, + CU.[ReadOnly], + CU.[HidePasswords], + CU.[Manage] +FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = [OU].[Id] +WHERE + [OrganizationUserId] = @Id +END +GO + +-- Readonly function that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER FUNCTION [dbo].[UserCollectionDetails](@UserId UNIQUEIDENTIFIER) +RETURNS TABLE +AS RETURN +SELECT + C.*, + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR COALESCE(CU.[ReadOnly], CG.[ReadOnly], 0) = 0 + THEN 0 + ELSE 1 + END [ReadOnly], + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR COALESCE(CU.[HidePasswords], CG.[HidePasswords], 0) = 0 + THEN 0 + ELSE 1 + END [HidePasswords], + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR COALESCE(CU.[Manage], CG.[Manage], 0) = 0 + THEN 0 + ELSE 1 + END [Manage] +FROM + [dbo].[CollectionView] C +INNER JOIN + [dbo].[OrganizationUser] OU ON C.[OrganizationId] = OU.[OrganizationId] +INNER JOIN + [dbo].[Organization] O ON O.[Id] = C.[OrganizationId] +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 + OU.[UserId] = @UserId + AND OU.[Status] = 2 -- 2 = Confirmed + AND O.[Enabled] = 1 + AND ( + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL ) +GO + +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON SELECT - [Id], - @Id, + Id, + OrganizationId, + [Name], + CreationDate, + RevisionDate, + ExternalId, + MIN([ReadOnly]) AS [ReadOnly], + MIN([HidePasswords]) AS [HidePasswords], + MIN([Manage]) AS [Manage] + FROM + [dbo].[UserCollectionDetails](@UserId) + WHERE + [Id] = @Id + GROUP BY + Id, + OrganizationId, + [Name], + CreationDate, + RevisionDate, + ExternalId +END +GO + +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + Id, + OrganizationId, + [Name], + CreationDate, + RevisionDate, + ExternalId, + MIN([ReadOnly]) AS [ReadOnly], + MIN([HidePasswords]) AS [HidePasswords], + MIN([Manage]) AS [Manage] + FROM + [dbo].[UserCollectionDetails](@UserId) + GROUP BY + Id, + OrganizationId, + [Name], + CreationDate, + RevisionDate, + ExternalId +END +GO + +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadWithGroupsAndUsersByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @TempUserCollections TABLE( + Id UNIQUEIDENTIFIER, + OrganizationId UNIQUEIDENTIFIER, + Name VARCHAR(MAX), + CreationDate DATETIME2(7), + RevisionDate DATETIME2(7), + ExternalId NVARCHAR(300), + ReadOnly BIT, + HidePasswords BIT, + Manage BIT) + + INSERT INTO @TempUserCollections EXEC [dbo].[Collection_ReadByUserId] @UserId + + SELECT + * + FROM + @TempUserCollections C + + SELECT + CG.* + FROM + [dbo].[CollectionGroup] CG + INNER JOIN + @TempUserCollections C ON C.[Id] = CG.[CollectionId] + + SELECT + CU.* + FROM + [dbo].[CollectionUser] CU + INNER JOIN + @TempUserCollections C ON C.[Id] = CU.[CollectionId] + +END +GO + +-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server +CREATE OR ALTER PROCEDURE [dbo].[Group_ReadWithCollectionsById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_ReadById] @Id + + SELECT + [CollectionId] [Id], [ReadOnly], [HidePasswords], [Manage] FROM - @Collections + [dbo].[CollectionGroup] WHERE - [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) - - EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + [GroupId] = @Id END GO -CREATE PROCEDURE [dbo].[CollectionUser_UpdateUsers] +-- END Update procedures that support backwards compatability in place + +-- BEGIN Create V2 of existing procedures to support new [Manage] column and new CollectionAccessSelectionType + +CREATE OR ALTER PROCEDURE [dbo].[CollectionUser_UpdateUsers_V2] @CollectionId UNIQUEIDENTIFIER, - @Users AS [dbo].[SelectionReadOnlyArray] READONLY + @Users AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -192,8 +357,14 @@ BEGIN ) -- Insert - INSERT INTO - [dbo].[CollectionUser] + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) SELECT @CollectionId, [Source].[Id], @@ -214,7 +385,7 @@ BEGIN [CollectionId] = @CollectionId AND [OrganizationUserId] = [Source].[Id] ) - + -- Delete DELETE CU @@ -235,7 +406,7 @@ BEGIN END GO -CREATE PROCEDURE [dbo].[Group_UpdateWithCollections] +CREATE OR ALTER PROCEDURE [dbo].[Group_UpdateWithCollections_V2] @Id UNIQUEIDENTIFIER, @OrganizationId UNIQUEIDENTIFIER, @Name NVARCHAR(100), @@ -243,7 +414,7 @@ CREATE PROCEDURE [dbo].[Group_UpdateWithCollections] @ExternalId NVARCHAR(300), @CreationDate DATETIME2(7), @RevisionDate DATETIME2(7), - @Collections AS [dbo].[SelectionReadOnlyArray] READONLY + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -260,14 +431,22 @@ BEGIN ) MERGE [dbo].[CollectionGroup] AS [Target] - USING + USING @Collections AS [Source] ON [Target].[CollectionId] = [Source].[Id] AND [Target].[GroupId] = @Id WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN - INSERT VALUES + INSERT + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( [Source].[Id], @Id, @@ -292,15 +471,15 @@ BEGIN END GO -CREATE PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers] +CREATE OR ALTER PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers_V2] @Id UNIQUEIDENTIFIER, @OrganizationId UNIQUEIDENTIFIER, @Name VARCHAR(MAX), @ExternalId NVARCHAR(300), @CreationDate DATETIME2(7), @RevisionDate DATETIME2(7), - @Groups AS [dbo].[SelectionReadOnlyArray] READONLY, - @Users AS [dbo].[SelectionReadOnlyArray] READONLY + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -318,14 +497,22 @@ BEGIN ) MERGE [dbo].[CollectionGroup] AS [Target] - USING + USING @Groups AS [Source] ON [Target].[CollectionId] = @Id AND [Target].[GroupId] = [Source].[Id] WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT VALUES + INSERT -- Add explicit column list + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( @Id, [Source].[Id], @@ -357,14 +544,22 @@ BEGIN ) MERGE [dbo].[CollectionUser] AS [Target] - USING + USING @Users AS [Source] ON [Target].[CollectionId] = @Id AND [Target].[OrganizationUserId] = [Source].[Id] WHEN NOT MATCHED BY TARGET AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN - INSERT VALUES + INSERT + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( @Id, [Source].[Id], @@ -389,7 +584,7 @@ BEGIN END GO -CREATE PROCEDURE [dbo].[OrganizationUser_CreateWithCollections] +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections_V2] @Id UNIQUEIDENTIFIER, @OrganizationId UNIQUEIDENTIFIER, @UserId UNIQUEIDENTIFIER, @@ -403,58 +598,7 @@ CREATE PROCEDURE [dbo].[OrganizationUser_CreateWithCollections] @RevisionDate DATETIME2(7), @Permissions NVARCHAR(MAX), @ResetPasswordKey VARCHAR(MAX), - @Collections AS [dbo].[SelectionReadOnlyArray] READONLY, - @AccessSecretsManager BIT = 0 -AS -BEGIN - SET NOCOUNT ON - - EXEC [dbo].[OrganizationUser_Create] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager - - ;WITH [AvailableCollectionsCTE] AS( - SELECT - [Id] - FROM - [dbo].[Collection] - WHERE - [OrganizationId] = @OrganizationId - ) - INSERT INTO [dbo].[CollectionUser] - ( - [CollectionId], - [OrganizationUserId], - [ReadOnly], - [HidePasswords], - [Manage] - ) - SELECT - [Id], - @Id, - [ReadOnly], - [HidePasswords], - [Manage] - FROM - @Collections - WHERE - [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) -END -GO - -CREATE PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] - @Id UNIQUEIDENTIFIER, - @OrganizationId UNIQUEIDENTIFIER, - @UserId UNIQUEIDENTIFIER, - @Email NVARCHAR(256), - @Key VARCHAR(MAX), - @Status SMALLINT, - @Type TINYINT, - @AccessAll BIT, - @ExternalId NVARCHAR(300), - @CreationDate DATETIME2(7), - @RevisionDate DATETIME2(7), - @Permissions NVARCHAR(MAX), - @ResetPasswordKey VARCHAR(MAX), - @Collections AS [dbo].[SelectionReadOnlyArray] READONLY, + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY, @AccessSecretsManager BIT = 0 AS BEGIN @@ -481,8 +625,14 @@ BEGIN ) -- Insert - INSERT INTO - [dbo].[CollectionUser] + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) SELECT [Source].[Id], @Id, @@ -522,15 +672,112 @@ BEGIN END GO -CREATE PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers] +CREATE OR ALTER PROCEDURE [dbo].[Group_CreateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name NVARCHAR(100), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_Create] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + [Id], + @Id, + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_CreateWithCollections_V2] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(256), + @Key VARCHAR(MAX), + @Status SMALLINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Permissions NVARCHAR(MAX), + @ResetPasswordKey VARCHAR(MAX), + @Collections AS [dbo].[CollectionAccessSelectionType] READONLY, + @AccessSecretsManager BIT = 0 +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Create] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + [Id], + @Id, + [ReadOnly], + [HidePasswords], + [Manage] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) +END +GO + +CREATE OR ALTER PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers_V2] @Id UNIQUEIDENTIFIER, @OrganizationId UNIQUEIDENTIFIER, @Name VARCHAR(MAX), @ExternalId NVARCHAR(300), @CreationDate DATETIME2(7), @RevisionDate DATETIME2(7), - @Groups AS [dbo].[SelectionReadOnlyArray] READONLY, - @Users AS [dbo].[SelectionReadOnlyArray] READONLY + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -596,199 +843,3 @@ BEGIN EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId END GO - -CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadWithCollectionsById] - @Id UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON - - EXEC [OrganizationUserUserDetails_ReadById] @Id - - SELECT - CU.[CollectionId] Id, - CU.[ReadOnly], - CU.[HidePasswords], - CU.[Manage] - FROM - [dbo].[OrganizationUser] OU - INNER JOIN - [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = [OU].[Id] - WHERE - [OrganizationUserId] = @Id -END -GO - -CREATE OR ALTER FUNCTION [dbo].[UserCollectionDetails](@UserId UNIQUEIDENTIFIER) -RETURNS TABLE -AS RETURN -SELECT - C.*, - CASE - WHEN - OU.[AccessAll] = 1 - OR G.[AccessAll] = 1 - OR COALESCE(CU.[ReadOnly], CG.[ReadOnly], 0) = 0 - THEN 0 - ELSE 1 - END [ReadOnly], - CASE - WHEN - OU.[AccessAll] = 1 - OR G.[AccessAll] = 1 - OR COALESCE(CU.[HidePasswords], CG.[HidePasswords], 0) = 0 - THEN 0 - ELSE 1 - END [HidePasswords], - CASE - WHEN - OU.[AccessAll] = 1 - OR G.[AccessAll] = 1 - OR COALESCE(CU.[Manage], CG.[Manage], 0) = 0 - THEN 0 - ELSE 1 - END [Manage] -FROM - [dbo].[CollectionView] C -INNER JOIN - [dbo].[OrganizationUser] OU ON C.[OrganizationId] = OU.[OrganizationId] -INNER JOIN - [dbo].[Organization] O ON O.[Id] = C.[OrganizationId] -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 - OU.[UserId] = @UserId - AND OU.[Status] = 2 -- 2 = Confirmed - AND O.[Enabled] = 1 - AND ( - OU.[AccessAll] = 1 - OR CU.[CollectionId] IS NOT NULL - OR G.[AccessAll] = 1 - OR CG.[CollectionId] IS NOT NULL - ) -GO - -CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByIdUserId] - @Id UNIQUEIDENTIFIER, - @UserId UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON - SELECT - Id, - OrganizationId, - [Name], - CreationDate, - RevisionDate, - ExternalId, - MIN([ReadOnly]) AS [ReadOnly], - MIN([HidePasswords]) AS [HidePasswords], - MIN([Manage]) AS [Manage] - FROM - [dbo].[UserCollectionDetails](@UserId) - WHERE - [Id] = @Id - GROUP BY - Id, - OrganizationId, - [Name], - CreationDate, - RevisionDate, - ExternalId -END -GO - -CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByUserId] - @UserId UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON - - SELECT - Id, - OrganizationId, - [Name], - CreationDate, - RevisionDate, - ExternalId, - MIN([ReadOnly]) AS [ReadOnly], - MIN([HidePasswords]) AS [HidePasswords], - MIN([Manage]) AS [Manage] - FROM - [dbo].[UserCollectionDetails](@UserId) - GROUP BY - Id, - OrganizationId, - [Name], - CreationDate, - RevisionDate, - ExternalId -END -GO - -CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadWithGroupsAndUsersByUserId] - @UserId UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON - - DECLARE @TempUserCollections TABLE( - Id UNIQUEIDENTIFIER, - OrganizationId UNIQUEIDENTIFIER, - Name VARCHAR(MAX), - CreationDate DATETIME2(7), - RevisionDate DATETIME2(7), - ExternalId NVARCHAR(300), - ReadOnly BIT, - HidePasswords BIT, - Manage BIT) - - INSERT INTO @TempUserCollections EXEC [dbo].[Collection_ReadByUserId] @UserId - - SELECT - * - FROM - @TempUserCollections C - - SELECT - CG.* - FROM - [dbo].[CollectionGroup] CG - INNER JOIN - @TempUserCollections C ON C.[Id] = CG.[CollectionId] - - SELECT - CU.* - FROM - [dbo].[CollectionUser] CU - INNER JOIN - @TempUserCollections C ON C.[Id] = CU.[CollectionId] - -END -GO - -CREATE OR ALTER PROCEDURE [dbo].[Group_ReadWithCollectionsById] - @Id UNIQUEIDENTIFIER -AS -BEGIN - SET NOCOUNT ON - - EXEC [dbo].[Group_ReadById] @Id - - SELECT - [CollectionId] [Id], - [ReadOnly], - [HidePasswords], - [Manage] - FROM - [dbo].[CollectionGroup] - WHERE - [GroupId] = @Id -END -GO diff --git a/util/Migrator/DbScripts/2023-08-25_00_BulkAddCollectionAccess.sql b/util/Migrator/DbScripts/2023-10-17_02_BulkAddCollectionAccess.sql similarity index 89% rename from util/Migrator/DbScripts/2023-08-25_00_BulkAddCollectionAccess.sql rename to util/Migrator/DbScripts/2023-10-17_02_BulkAddCollectionAccess.sql index d45d7dc5bd..f185624b0a 100644 --- a/util/Migrator/DbScripts/2023-08-25_00_BulkAddCollectionAccess.sql +++ b/util/Migrator/DbScripts/2023-10-17_02_BulkAddCollectionAccess.sql @@ -38,8 +38,8 @@ GO CREATE OR ALTER PROCEDURE [dbo].[Collection_CreateOrUpdateAccessForMany] @OrganizationId UNIQUEIDENTIFIER, @CollectionIds AS [dbo].[GuidIdArray] READONLY, - @Groups AS [dbo].[SelectionReadOnlyArray] READONLY, - @Users AS [dbo].[SelectionReadOnlyArray] READONLY + @Groups AS [dbo].[CollectionAccessSelectionType] READONLY, + @Users AS [dbo].[CollectionAccessSelectionType] READONLY AS BEGIN SET NOCOUNT ON @@ -78,7 +78,15 @@ BEGIN [Target].[HidePasswords] = [Source].[HidePasswords], [Target].[Manage] = [Source].[Manage] WHEN NOT MATCHED BY TARGET - THEN INSERT VALUES + THEN INSERT + ( + [CollectionId], + [GroupId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( [Source].[CollectionId], [Source].[GroupId], @@ -121,7 +129,15 @@ BEGIN [Target].[HidePasswords] = [Source].[HidePasswords], [Target].[Manage] = [Source].[Manage] WHEN NOT MATCHED BY TARGET - THEN INSERT VALUES + THEN INSERT + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + VALUES ( [Source].[CollectionId], [Source].[OrganizationUserId], diff --git a/util/Migrator/DbScripts_finalization/2023-10-FutureMigrations.sql b/util/Migrator/DbScripts_finalization/2023-10-FutureMigrations.sql new file mode 100644 index 0000000000..e7dfd2f770 --- /dev/null +++ b/util/Migrator/DbScripts_finalization/2023-10-FutureMigrations.sql @@ -0,0 +1,50 @@ +-- Remove old stored procedures and SelectionReadOnlyArray for Flexible Collections +-- They have been superseded via their respective _V2 variants and the CollectionAccessSelectionType + +IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers] +END +GO + +IF OBJECT_ID('[dbo].[Group_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Group_UpdateWithCollections] +END +GO + +IF OBJECT_ID('[dbo].[Collection_UpdateWithGroupsAndUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers] +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] +END +GO + +IF OBJECT_ID('[dbo].[Group_CreateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Group_CreateWithCollections] +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_CreateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_CreateWithCollections] +END +GO + +IF OBJECT_ID('[dbo].[Collection_CreateWithGroupsAndUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers] +END +GO + +IF TYPE_ID('[dbo].[SelectionReadOnlyArray]') IS NOT NULL +BEGIN + DROP TYPE [dbo].[SelectionReadOnlyArray] +END +GO