From 8427367c764a1c8c5bc54433e1d932002e43fd2d Mon Sep 17 00:00:00 2001 From: Thomas Rittson Date: Fri, 2 Jan 2026 08:36:12 +1000 Subject: [PATCH] Use guid array instead of json --- .../Repositories/CollectionRepository.cs | 3 +- .../Collection_CreateDefaultCollections.sql | 36 +++++++++---------- .../CreateDefaultCollectionsTests.cs | 2 +- ...01_Collection_CreateDefaultCollections.sql | 26 +++++++------- 4 files changed, 34 insertions(+), 33 deletions(-) diff --git a/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs b/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs index 9a14612e14..f9b1a2c0f3 100644 --- a/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs +++ b/src/Infrastructure.Dapper/Repositories/CollectionRepository.cs @@ -373,14 +373,13 @@ public class CollectionRepository : Repository, ICollectionRep try { - var organizationUserIdsJson = JsonSerializer.Serialize(organizationUserIds); await connection.ExecuteAsync( "[dbo].[Collection_CreateDefaultCollections]", new { OrganizationId = organizationId, DefaultCollectionName = defaultCollectionName, - OrganizationUserIdsJson = organizationUserIdsJson + OrganizationUserIds = organizationUserIds.ToGuidIdArrayTVP() }, commandType: CommandType.StoredProcedure); } diff --git a/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_CreateDefaultCollections.sql b/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_CreateDefaultCollections.sql index 98c6ee3b18..f1c87e3b90 100644 --- a/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_CreateDefaultCollections.sql +++ b/src/Sql/dbo/AdminConsole/Stored Procedures/Collection_CreateDefaultCollections.sql @@ -1,32 +1,32 @@ -- Creates default user collections for organization users -- Uses semaphore table to prevent duplicate default collections at database level --- Cascade behavior: Organization -> OrganizationUser (CASCADE) -> DefaultCollectionSemaphore (CASCADE) --- Organization FK uses NoAction to avoid competing cascade paths CREATE PROCEDURE [dbo].[Collection_CreateDefaultCollections] @OrganizationId UNIQUEIDENTIFIER, @DefaultCollectionName VARCHAR(MAX), - @OrganizationUserIdsJson NVARCHAR(MAX) + @OrganizationUserIds AS [dbo].[GuidIdArray] READONLY AS BEGIN SET NOCOUNT ON - -- Parse JSON once into table variable with pre-generated collection IDs - DECLARE @OrganizationUserIds TABLE - ( - [OrganizationUserId] UNIQUEIDENTIFIER, - [CollectionId] UNIQUEIDENTIFIER - ); + DECLARE @Now DATETIME2(7) = GETUTCDATE() - INSERT INTO @OrganizationUserIds + -- Create temporary table to allocate collection IDs to each organizationUser + DECLARE @CollectionsToInsert TABLE + ( + [OrganizationUserId] UNIQUEIDENTIFIER, + [CollectionId] UNIQUEIDENTIFIER + ); + + INSERT INTO @CollectionsToInsert ( [OrganizationUserId], [CollectionId] ) SELECT - CAST([value] AS UNIQUEIDENTIFIER), + ou.Id, NEWID() FROM - OPENJSON(@OrganizationUserIdsJson); + @OrganizationUserIds ou BEGIN TRANSACTION; @@ -40,9 +40,9 @@ BEGIN ) SELECT ou.[OrganizationUserId], - GETUTCDATE() + @Now FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; -- Insert collections for users who obtained semaphore entries INSERT INTO [dbo].[Collection] @@ -60,13 +60,13 @@ BEGIN ou.[CollectionId], @OrganizationId, @DefaultCollectionName, - GETUTCDATE(), - GETUTCDATE(), + @Now, + @Now, 1, -- CollectionType.DefaultUserCollection NULL, NULL FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; -- Insert collection user mappings INSERT INTO [dbo].[CollectionUser] @@ -84,7 +84,7 @@ BEGIN 0, -- HidePasswords = false 1 -- Manage = true FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; COMMIT TRANSACTION; END TRY diff --git a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs index 120951b302..224a9bdc29 100644 --- a/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs +++ b/test/Infrastructure.IntegrationTest/AdminConsole/Repositories/CollectionRepository/CreateDefaultCollectionsTests.cs @@ -71,7 +71,7 @@ public class CreateDefaultCollectionsTests /// Test that calling CreateDefaultCollectionsAsync multiple times does NOT create duplicates /// [Theory, DatabaseData] - public async Task CreateDefaultCollectionsAsync_CalledMultipleTimes_DoesNotCreateDuplicates( + public async Task CreateDefaultCollectionsAsync_CalledMultipleTimesForSameOrganizationUser_Throws( IUserRepository userRepository, IOrganizationRepository organizationRepository, ICollectionRepository collectionRepository, diff --git a/util/Migrator/DbScripts/2025-12-30_01_Collection_CreateDefaultCollections.sql b/util/Migrator/DbScripts/2025-12-30_01_Collection_CreateDefaultCollections.sql index 3e8fe14b1a..401e58005c 100644 --- a/util/Migrator/DbScripts/2025-12-30_01_Collection_CreateDefaultCollections.sql +++ b/util/Migrator/DbScripts/2025-12-30_01_Collection_CreateDefaultCollections.sql @@ -1,28 +1,30 @@ CREATE OR ALTER PROCEDURE [dbo].[Collection_CreateDefaultCollections] @OrganizationId UNIQUEIDENTIFIER, @DefaultCollectionName VARCHAR(MAX), - @OrganizationUserIdsJson NVARCHAR(MAX) + @OrganizationUserIds AS [dbo].[GuidIdArray] READONLY AS BEGIN SET NOCOUNT ON - -- Parse JSON once into table variable with pre-generated collection IDs - DECLARE @OrganizationUserIds TABLE + DECLARE @Now DATETIME2(7) = GETUTCDATE() + + -- Create temporary table to allocate collection IDs to each organizationUser + DECLARE @CollectionsToInsert TABLE ( [OrganizationUserId] UNIQUEIDENTIFIER, [CollectionId] UNIQUEIDENTIFIER ); - INSERT INTO @OrganizationUserIds + INSERT INTO @CollectionsToInsert ( [OrganizationUserId], [CollectionId] ) SELECT - CAST([value] AS UNIQUEIDENTIFIER), + ou.Id, NEWID() FROM - OPENJSON(@OrganizationUserIdsJson); + @OrganizationUserIds ou BEGIN TRANSACTION; @@ -36,9 +38,9 @@ BEGIN ) SELECT ou.[OrganizationUserId], - GETUTCDATE() + @Now FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; -- Insert collections for users who obtained semaphore entries INSERT INTO [dbo].[Collection] @@ -56,13 +58,13 @@ BEGIN ou.[CollectionId], @OrganizationId, @DefaultCollectionName, - GETUTCDATE(), - GETUTCDATE(), + @Now, + @Now, 1, -- CollectionType.DefaultUserCollection NULL, NULL FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; -- Insert collection user mappings INSERT INTO [dbo].[CollectionUser] @@ -80,7 +82,7 @@ BEGIN 0, -- HidePasswords = false 1 -- Manage = true FROM - @OrganizationUserIds ou; + @CollectionsToInsert ou; COMMIT TRANSACTION; END TRY