/* * 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