From afaaea03473b4a37396bce7daefc9401418dc624 Mon Sep 17 00:00:00 2001 From: Thomas Rittson Date: Sat, 27 Dec 2025 08:53:54 +1000 Subject: [PATCH] First pass at handling existing data and duplicates --- ...AddDefaultCollectionOwnerAndConstraint.sql | 61 ++++++++++++++++++- 1 file changed, 60 insertions(+), 1 deletion(-) diff --git a/util/Migrator/DbScripts/2025-12-20_00_Collection_AddDefaultCollectionOwnerAndConstraint.sql b/util/Migrator/DbScripts/2025-12-20_00_Collection_AddDefaultCollectionOwnerAndConstraint.sql index af7498b873..19150cc9c3 100644 --- a/util/Migrator/DbScripts/2025-12-20_00_Collection_AddDefaultCollectionOwnerAndConstraint.sql +++ b/util/Migrator/DbScripts/2025-12-20_00_Collection_AddDefaultCollectionOwnerAndConstraint.sql @@ -1,4 +1,4 @@ --- TODO! Handle existing data in MSSQL (and EF if releasing before this). This assumes the column is populated, if it isn't then it'll create at least 1 duplicate. +-- TODO! Handle existing data in EF if releasing before this. This assumes the column is populated, if it isn't then it'll create at least 1 duplicate. -- Add DefaultCollectionOwnerId column to Collection table for Type=1 collections -- This enables a filtered unique constraint to prevent duplicate default collections @@ -15,6 +15,65 @@ BEGIN END GO +-- Populate DefaultCollectionOwnerId for existing Type=1 collections +-- Find the OrganizationUser with Manage permissions on each default collection +IF EXISTS ( + SELECT * + FROM INFORMATION_SCHEMA.COLUMNS + WHERE TABLE_SCHEMA = 'dbo' + AND TABLE_NAME = 'Collection' + AND COLUMN_NAME = 'DefaultCollectionOwnerId' +) +BEGIN + UPDATE c + SET c.[DefaultCollectionOwnerId] = cu.[OrganizationUserId] + FROM [dbo].[Collection] c + INNER JOIN [dbo].[CollectionUser] cu ON c.[Id] = cu.[CollectionId] + WHERE c.[Type] = 1 + AND cu.[Manage] = 1 + AND c.[DefaultCollectionOwnerId] IS NULL +END +GO + +-- Handle duplicate default collections for the same user/organization +-- Convert duplicates to SharedCollections (Type=0), keeping the oldest one +IF EXISTS ( + SELECT * + FROM INFORMATION_SCHEMA.COLUMNS + WHERE TABLE_SCHEMA = 'dbo' + AND TABLE_NAME = 'Collection' + AND COLUMN_NAME = 'DefaultCollectionOwnerId' +) +BEGIN + DECLARE @UtcNow DATETIME2(7) = GETUTCDATE(); + + -- Find duplicate default collections (same OrganizationUserId + OrganizationId + Type=1) + -- Keep the oldest one, convert the rest to SharedCollections + WITH DuplicateCollections AS ( + SELECT + c.[Id], + c.[OrganizationId], + c.[DefaultCollectionOwnerId], + c.[CreationDate], + ROW_NUMBER() OVER ( + PARTITION BY c.[DefaultCollectionOwnerId], c.[OrganizationId] + ORDER BY c.[CreationDate] ASC + ) AS RowNum + FROM [dbo].[Collection] c + WHERE c.[Type] = 1 + AND c.[DefaultCollectionOwnerId] IS NOT NULL + ) + UPDATE c + SET + c.[Type] = 0, -- Convert to SharedCollection + c.[DefaultCollectionOwnerId] = NULL, + c.[RevisionDate] = @UtcNow + FROM [dbo].[Collection] c + INNER JOIN DuplicateCollections dc ON c.[Id] = dc.[Id] + WHERE dc.RowNum > 1 -- Keep only the first (oldest) collection +END +GO + -- Add foreign key constraint to OrganizationUser IF NOT EXISTS ( SELECT *