-- Step 1: AccessAll migration for Groups -- Create a temporary table to store the groups with AccessAll = true CREATE TEMPORARY TABLE "TempGroupsAccessAll" AS SELECT "G"."Id" AS "GroupId", "G"."OrganizationId" FROM "Group" "G" INNER JOIN "Organization" "O" ON "G"."OrganizationId" = "O"."Id" WHERE "O"."FlexibleCollections" = false AND "G"."AccessAll" = true; -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = true CREATE TEMPORARY TABLE "TempUsersAccessAll" AS SELECT "OU"."Id" AS "OrganizationUserId", "OU"."OrganizationId" FROM "OrganizationUser" "OU" INNER JOIN "Organization" "O" ON "OU"."OrganizationId" = "O"."Id" WHERE "O"."FlexibleCollections" = false AND "OU"."AccessAll" = true; -- Step 3: For all OrganizationUsers with Manager role or 'EditAssignedCollections' permission update their existing CollectionUsers rows and insert new rows with Manage = 1 -- and finally update all OrganizationUsers with Manager role to User role -- Create a temporary table to store the OrganizationUsers with Manager role or 'EditAssignedCollections' permission CREATE TEMPORARY TABLE "TempUserManagers" AS SELECT "OU"."Id" AS "OrganizationUserId", "OU"."OrganizationId", CASE WHEN "OU"."Type" = 3 THEN true ELSE false END AS "IsManager" FROM "OrganizationUser" "OU" INNER JOIN "Organization" "O" ON "OU"."OrganizationId" = "O"."Id" WHERE "O"."FlexibleCollections" = false AND ("OU"."Type" = 3 OR ("OU"."Type" = 4 AND "OU"."Permissions" IS NOT NULL AND (("OU"."Permissions"::text)::jsonb->>'editAssignedCollections') = 'true')); -- Step 1 -- Update existing rows in CollectionGroups UPDATE "CollectionGroups" "CG" SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = false WHERE "CG"."CollectionId" IN ( SELECT "C"."Id" FROM "Collection" "C" INNER JOIN "TempGroupsAccessAll" "TG" ON "C"."OrganizationId" = "TG"."OrganizationId" WHERE "CG"."GroupId" = "TG"."GroupId" ); -- Insert new rows into CollectionGroups INSERT INTO "CollectionGroups" ("CollectionId", "GroupId", "ReadOnly", "HidePasswords", "Manage") SELECT "C"."Id", "TG"."GroupId", false, false, false FROM "Collection" "C" INNER JOIN "TempGroupsAccessAll" "TG" ON "C"."OrganizationId" = "TG"."OrganizationId" LEFT JOIN "CollectionGroups" "CG" ON "C"."Id" = "CG"."CollectionId" AND "TG"."GroupId" = "CG"."GroupId" WHERE "CG"."CollectionId" IS NULL; -- Update "Group" to clear "AccessAll" flag and update "RevisionDate" UPDATE "Group" "G" SET "AccessAll" = false, "RevisionDate" = CURRENT_TIMESTAMP WHERE "G"."Id" IN (SELECT "GroupId" FROM "TempGroupsAccessAll"); -- Step 2 -- Update existing rows in CollectionUsers UPDATE "CollectionUsers" "CU" SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = false WHERE "CU"."CollectionId" IN ( SELECT "C"."Id" FROM "Collection" "C" INNER JOIN "TempUsersAccessAll" "TU" ON "C"."OrganizationId" = "TU"."OrganizationId" WHERE "CU"."OrganizationUserId" = "TU"."OrganizationUserId" ); -- Insert new rows into CollectionUsers INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage") SELECT "C"."Id", "TU"."OrganizationUserId", false, false, false FROM "Collection" "C" INNER JOIN "TempUsersAccessAll" "TU" ON "C"."OrganizationId" = "TU"."OrganizationId" LEFT JOIN "CollectionUsers" "target" ON "C"."Id" = "target"."CollectionId" AND "TU"."OrganizationUserId" = "target"."OrganizationUserId" WHERE "target"."CollectionId" IS NULL; -- Update "OrganizationUser" to clear "AccessAll" flag UPDATE "OrganizationUser" "OU" SET "AccessAll" = false, "RevisionDate" = CURRENT_TIMESTAMP WHERE "OU"."Id" IN (SELECT "OrganizationUserId" FROM "TempUsersAccessAll"); -- Step 3 -- Update CollectionUsers with Manage = 1 using the temporary table UPDATE "CollectionUsers" "CU" SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = true FROM "TempUserManagers" "TUM" WHERE "CU"."OrganizationUserId" = "TUM"."OrganizationUserId"; -- Insert rows to CollectionUsers with Manage = true using the temporary table -- This is for orgUsers who are Managers / EditAssignedCollections but have access via a group -- We cannot give the whole group Manage permissions so we have to give them a direct assignment INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage") SELECT DISTINCT "CG"."CollectionId", "TUM"."OrganizationUserId", false, false, true FROM "CollectionGroups" "CG" INNER JOIN "GroupUser" "GU" ON "CG"."GroupId" = "GU"."GroupId" INNER JOIN "TempUserManagers" "TUM" ON "GU"."OrganizationUserId" = "TUM"."OrganizationUserId" WHERE NOT EXISTS ( SELECT 1 FROM "CollectionUsers" "CU" WHERE "CU"."CollectionId" = "CG"."CollectionId" AND "CU"."OrganizationUserId" = "TUM"."OrganizationUserId" ); -- Update "OrganizationUser" to migrate all OrganizationUsers with Manager role to User role UPDATE "OrganizationUser" "OU" SET "Type" = 2, "RevisionDate" = CURRENT_TIMESTAMP -- User WHERE "OU"."Id" IN (SELECT "OrganizationUserId" FROM "TempUserManagers" WHERE "IsManager" = true); -- Step 4 -- Update "User" "AccountRevisionDate" for each unique "OrganizationUserId" UPDATE "User" "U" SET "AccountRevisionDate" = CURRENT_TIMESTAMP FROM "OrganizationUser" "OU" WHERE "U"."Id" = "OU"."UserId" AND "OU"."Id" IN ( SELECT "OrganizationUserId" FROM "GroupUser" WHERE "GroupId" IN (SELECT "GroupId" FROM "TempGroupsAccessAll") UNION SELECT "OrganizationUserId" FROM "TempUsersAccessAll" UNION SELECT "OrganizationUserId" FROM "TempUserManagers" ); -- Step 5: Set "FlexibleCollections" = true for all organizations that have not yet been migrated. UPDATE "Organization" SET "FlexibleCollections" = true WHERE "FlexibleCollections" = false; -- Step 6: Drop the temporary tables DROP TABLE IF EXISTS "TempGroupsAccessAll"; DROP TABLE IF EXISTS "TempUsersAccessAll"; DROP TABLE IF EXISTS "TempUserManagers";