-- Step 1: Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission -- Create a temporary table CREATE TEMP TABLE IF NOT EXISTS TempOrgUser AS SELECT ou."Id" AS "OrganizationUserId" FROM "OrganizationUser" ou WHERE (ou."Type" = 3 OR (ou."Permissions" IS NOT NULL AND ((ou."Permissions"::text)::jsonb->>'editAssignedCollections') = 'true')); -- Update CollectionUsers with Manage = 1 using the temporary table UPDATE "CollectionUsers" cu SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = true FROM TempOrgUser temp WHERE cu."OrganizationUserId" = temp."OrganizationUserId"; -- Update `User` AccountRevisionDate for each unique OrganizationUserId UPDATE "User" AS U SET "AccountRevisionDate" = current_timestamp FROM "OrganizationUser" AS OU JOIN TempOrgUser AS TOU ON OU."Id" = TOU."OrganizationUserId" WHERE OU."Status" = 2 AND U."Id" = OU."UserId"; -- Drop the temporary table DROP TABLE IF EXISTS TempOrgUser; -- Step 2: Insert rows to CollectionUser for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access -- Store the results in a temporary table CREATE TEMP TABLE IF NOT EXISTS TempCol AS SELECT cg."CollectionId", ou."Id" AS "OrganizationUserId" FROM "CollectionGroups" cg INNER JOIN "GroupUser" gu ON cg."GroupId" = gu."GroupId" INNER JOIN "OrganizationUser" ou ON gu."OrganizationUserId" = ou."Id" WHERE (ou."Type" = 3 OR (ou."Permissions" IS NOT NULL AND ((ou."Permissions"::text)::jsonb->>'editAssignedCollections') = 'true')) AND NOT EXISTS ( SELECT 1 FROM "CollectionUsers" cu WHERE cu."CollectionId" = cg."CollectionId" AND cu."OrganizationUserId" = ou."Id" ); -- Insert rows into CollectionUsers using the temporary table INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage") SELECT "CollectionId", "OrganizationUserId", false, false, true FROM TempCol; -- Update `User` AccountRevisionDate for each unique OrganizationUserId UPDATE "User" AS U SET "AccountRevisionDate" = current_timestamp FROM "OrganizationUser" AS OU JOIN TempCol AS TC ON OU."Id" = TC."OrganizationUserId" WHERE OU."Status" = 2 AND U."Id" = OU."UserId"; -- Drop the temporary table DROP TABLE IF EXISTS TempCol; -- Step 3: Set all Managers to Users -- Create a temporary table CREATE TEMP TABLE IF NOT EXISTS TempOrgUser AS SELECT ou."Id" AS "OrganizationUserId" FROM "OrganizationUser" ou WHERE ou."Type" = 3; -- Update OrganizationUser with Type = 2 using the temporary table UPDATE "OrganizationUser" ou SET "Type" = 2 FROM TempOrgUser temp WHERE ou."Id" = temp."OrganizationUserId"; -- Update `User` AccountRevisionDate for each unique OrganizationUserId UPDATE "User" AS U SET "AccountRevisionDate" = current_timestamp FROM "OrganizationUser" AS OU JOIN TempOrgUser AS TOU ON OU."Id" = TOU."OrganizationUserId" WHERE OU."Status" = 2 AND U."Id" = OU."UserId"; -- Drop the temporary table DROP TABLE IF EXISTS TempOrgUser;