From 36aad90cb8e9f1973615375fe688f541210ea954 Mon Sep 17 00:00:00 2001 From: Thomas Rittson Date: Wed, 31 Dec 2025 14:25:14 +1000 Subject: [PATCH] Explicit transaction for mssql --- .../Collection_UpsertDefaultCollections.sql | 119 ++++++++++-------- .../CreateDefaultCollectionsTests.cs | 2 +- ...01_Collection_UpsertDefaultCollections.sql | 119 ++++++++++-------- 3 files changed, 133 insertions(+), 107 deletions(-) diff --git a/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_UpsertDefaultCollections.sql b/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_UpsertDefaultCollections.sql index b0adce75c1..6c6be401df 100644 --- a/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_UpsertDefaultCollections.sql +++ b/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_UpsertDefaultCollections.sql @@ -28,59 +28,72 @@ BEGIN FROM OPENJSON(@OrganizationUserIdsJson); - -- Insert semaphore entries first to obtain the "lock" - INSERT INTO [dbo].[DefaultCollectionSemaphore] - ( - [OrganizationId], - [OrganizationUserId], - [CreationDate] - ) - SELECT - @OrganizationId, - ou.[OrganizationUserId], - GETUTCDATE() - FROM - @OrganizationUserIds ou; + BEGIN TRANSACTION; - -- Insert collections for users who obtained semaphore entries - INSERT INTO [dbo].[Collection] - ( - [Id], - [OrganizationId], - [Name], - [CreationDate], - [RevisionDate], - [Type], - [ExternalId], - [DefaultUserCollectionEmail] - ) - SELECT - ou.[CollectionId], - @OrganizationId, - @DefaultCollectionName, - GETUTCDATE(), - GETUTCDATE(), - 1, -- CollectionType.DefaultUserCollection - NULL, - NULL - FROM - @OrganizationUserIds ou; + BEGIN TRY + -- Insert semaphore entries first to obtain the "lock" + -- If this fails due to duplicate key, the entire transaction will be rolled back + INSERT INTO [dbo].[DefaultCollectionSemaphore] + ( + [OrganizationId], + [OrganizationUserId], + [CreationDate] + ) + SELECT + @OrganizationId, + ou.[OrganizationUserId], + GETUTCDATE() + FROM + @OrganizationUserIds ou; - -- Insert collection user mappings - INSERT INTO [dbo].[CollectionUser] - ( - [CollectionId], - [OrganizationUserId], - [ReadOnly], - [HidePasswords], - [Manage] - ) - SELECT - ou.[CollectionId], - ou.[OrganizationUserId], - 0, -- ReadOnly = false - 0, -- HidePasswords = false - 1 -- Manage = true - FROM - @OrganizationUserIds ou; + -- Insert collections for users who obtained semaphore entries + INSERT INTO [dbo].[Collection] + ( + [Id], + [OrganizationId], + [Name], + [CreationDate], + [RevisionDate], + [Type], + [ExternalId], + [DefaultUserCollectionEmail] + ) + SELECT + ou.[CollectionId], + @OrganizationId, + @DefaultCollectionName, + GETUTCDATE(), + GETUTCDATE(), + 1, -- CollectionType.DefaultUserCollection + NULL, + NULL + FROM + @OrganizationUserIds ou; + + -- Insert collection user mappings + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + ou.[CollectionId], + ou.[OrganizationUserId], + 0, -- ReadOnly = false + 0, -- HidePasswords = false + 1 -- Manage = true + FROM + @OrganizationUserIds ou; + + COMMIT TRANSACTION; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION; + + THROW; + END CATCH END diff --git a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs index 5f81035b0c..852a11e0bc 100644 --- a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs +++ b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs @@ -92,7 +92,7 @@ public class CreateDefaultCollectionsTests collectionRepository.CreateDefaultCollectionsAsync( organization.Id, [orgUser.Id], - "My Items")); + "My Items Duplicate")); // Assert - Only one collection should exist var collections = await collectionRepository.GetManyByOrganizationIdAsync(organization.Id); diff --git a/util/Migrator/DbScripts/2025-12-30_01_Collection_UpsertDefaultCollections.sql b/util/Migrator/DbScripts/2025-12-30_01_Collection_UpsertDefaultCollections.sql index e773920442..55e727712c 100644 --- a/util/Migrator/DbScripts/2025-12-30_01_Collection_UpsertDefaultCollections.sql +++ b/util/Migrator/DbScripts/2025-12-30_01_Collection_UpsertDefaultCollections.sql @@ -24,60 +24,73 @@ BEGIN FROM OPENJSON(@OrganizationUserIdsJson); - -- Insert semaphore entries first to obtain the "lock" - INSERT INTO [dbo].[DefaultCollectionSemaphore] - ( - [OrganizationId], - [OrganizationUserId], - [CreationDate] - ) - SELECT - @OrganizationId, - ou.[OrganizationUserId], - GETUTCDATE() - FROM - @OrganizationUserIds ou; + BEGIN TRANSACTION; - -- Insert collections for users who obtained semaphore entries - INSERT INTO [dbo].[Collection] - ( - [Id], - [OrganizationId], - [Name], - [CreationDate], - [RevisionDate], - [Type], - [ExternalId], - [DefaultUserCollectionEmail] - ) - SELECT - ou.[CollectionId], - @OrganizationId, - @DefaultCollectionName, - GETUTCDATE(), - GETUTCDATE(), - 1, -- CollectionType.DefaultUserCollection - NULL, - NULL - FROM - @OrganizationUserIds ou; + BEGIN TRY + -- Insert semaphore entries first to obtain the "lock" + -- If this fails due to duplicate key, the entire transaction will be rolled back + INSERT INTO [dbo].[DefaultCollectionSemaphore] + ( + [OrganizationId], + [OrganizationUserId], + [CreationDate] + ) + SELECT + @OrganizationId, + ou.[OrganizationUserId], + GETUTCDATE() + FROM + @OrganizationUserIds ou; - -- Insert collection user mappings - INSERT INTO [dbo].[CollectionUser] - ( - [CollectionId], - [OrganizationUserId], - [ReadOnly], - [HidePasswords], - [Manage] - ) - SELECT - ou.[CollectionId], - ou.[OrganizationUserId], - 0, -- ReadOnly = false - 0, -- HidePasswords = false - 1 -- Manage = true - FROM - @OrganizationUserIds ou; + -- Insert collections for users who obtained semaphore entries + INSERT INTO [dbo].[Collection] + ( + [Id], + [OrganizationId], + [Name], + [CreationDate], + [RevisionDate], + [Type], + [ExternalId], + [DefaultUserCollectionEmail] + ) + SELECT + ou.[CollectionId], + @OrganizationId, + @DefaultCollectionName, + GETUTCDATE(), + GETUTCDATE(), + 1, -- CollectionType.DefaultUserCollection + NULL, + NULL + FROM + @OrganizationUserIds ou; + + -- Insert collection user mappings + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly], + [HidePasswords], + [Manage] + ) + SELECT + ou.[CollectionId], + ou.[OrganizationUserId], + 0, -- ReadOnly = false + 0, -- HidePasswords = false + 1 -- Manage = true + FROM + @OrganizationUserIds ou; + + COMMIT TRANSACTION; + END TRY + BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION; + + THROW; + END CATCH END GO