diff --git a/util/PostgresMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.psql b/util/PostgresMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.psql index c03220dd7a..31c064ea5d 100644 --- a/util/PostgresMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.psql +++ b/util/PostgresMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.psql @@ -4,18 +4,24 @@ SELECT "Id" AS "GroupId", "OrganizationId" FROM "Group" WHERE "AccessAll" = true; --- Step 2: Update existing rows in "CollectionGroup" +-- Step 2: Create a temporary table to store distinct OrganizationUserIds +CREATE TEMP TABLE IF NOT EXISTS TempOrganizationUsers AS +SELECT DISTINCT GU."OrganizationUserId" +FROM "GroupUser" GU +JOIN TempGroup TG ON GU."GroupId" = TG."GroupId"; + +-- Step 3: Update existing rows in "CollectionGroups" UPDATE "CollectionGroups" CG SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = false - FROM "CollectionGroups" CGUpdate +FROM "CollectionGroups" CGUpdate INNER JOIN "Collection" C ON CGUpdate."CollectionId" = C."Id" INNER JOIN TempGroup TG ON CGUpdate."GroupId" = TG."GroupId" WHERE C."OrganizationId" = TG."OrganizationId"; --- Step 3: Insert new rows into "CollectionGroup" +-- Step 4: Insert new rows into "CollectionGroups" INSERT INTO "CollectionGroups" ("CollectionId", "GroupId", "ReadOnly", "HidePasswords", "Manage") SELECT C."Id", TG."GroupId", false, false, false FROM "Collection" C @@ -23,5 +29,19 @@ INNER JOIN TempGroup TG ON C."OrganizationId" = TG."OrganizationId" LEFT JOIN "CollectionGroups" CG ON CG."CollectionId" = C."Id" AND CG."GroupId" = TG."GroupId" WHERE CG."CollectionId" IS NULL; --- Step 4: Drop the temporary table +-- Step 5: Update Group to clear AccessAll flag +UPDATE "Group" G +SET "AccessAll" = false +FROM TempGroup TG +WHERE G."Id" = TG."GroupId"; + +-- Step 6: Update User AccountRevisionDate for each unique OrganizationUserId +UPDATE "User" U +SET "AccountRevisionDate" = current_timestamp +FROM "OrganizationUser" OU +JOIN TempOrganizationUsers TOU ON OU."Id" = TOU."OrganizationUserId" +WHERE U."Id" = OU."UserId" AND OU."Status" = 2; + +-- Step 7: Drop the temporary tables DROP TABLE IF EXISTS TempGroup; +DROP TABLE IF EXISTS TempOrganizationUsers; diff --git a/util/PostgresMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.psql b/util/PostgresMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.psql index 210afcca10..4e9a659114 100644 --- a/util/PostgresMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.psql +++ b/util/PostgresMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.psql @@ -1,22 +1,43 @@ --- Update existing rows in CollectionUsers -UPDATE "CollectionUsers" +-- Step 1: Create a temporary table +CREATE TEMP TABLE IF NOT EXISTS TempOrgUser AS +SELECT "Id" AS "OrganizationUserId", "OrganizationId" +FROM "OrganizationUser" +WHERE "AccessAll" = true; + +-- Step 2: Update existing rows in CollectionUsers +UPDATE "CollectionUsers" cu SET "ReadOnly" = false, "HidePasswords" = false, "Manage" = false -FROM "Collection" AS C -INNER JOIN "CollectionUsers" AS CU ON CU."CollectionId" = C."Id" -INNER JOIN "OrganizationUser" AS OU ON CU."CollectionId" = C."Id" AND C."OrganizationId" = OU."OrganizationId" -WHERE OU."AccessAll" = true; +FROM "CollectionUsers" cuUpdate +INNER JOIN "Collection" C ON cuUpdate."CollectionId" = C."Id" +INNER JOIN TempOrgUser OU ON cuUpdate."OrganizationUserId" = OU."OrganizationUserId" +WHERE C."OrganizationId" = OU."OrganizationId"; --- Insert new rows into CollectionUsers +-- Step 3: Insert new rows into CollectionUsers INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage") -SELECT C."Id" AS "CollectionId", OU."Id" AS "OrganizationUserId", false, false, false +SELECT C."Id" AS "CollectionId", OU."OrganizationUserId", false, false, false FROM "Collection" AS C -INNER JOIN "OrganizationUser" AS OU ON C."OrganizationId" = OU."OrganizationId" -WHERE OU."AccessAll" = true - AND NOT EXISTS ( +INNER JOIN TempOrgUser AS OU ON C."OrganizationId" = OU."OrganizationId" +WHERE NOT EXISTS ( SELECT 1 FROM "CollectionUsers" AS CU - WHERE CU."CollectionId" = C."Id" AND CU."OrganizationUserId" = OU."Id" + WHERE CU."CollectionId" = C."Id" AND CU."OrganizationUserId" = OU."OrganizationUserId" ); + +-- Step 4: Update OrganizationUser to clear AccessAll flag +UPDATE "OrganizationUser" AS OU +SET "AccessAll" = false +FROM TempOrgUser AS T +WHERE OU."Id" = T."OrganizationUserId"; + +-- Step 5: 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 U."Id" = OU."UserId" AND OU."Status" = 2; + +-- Step 6: Drop the temporary table +DROP TABLE IF EXISTS TempOrgUser; diff --git a/util/PostgresMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.psql b/util/PostgresMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.psql index cbd972a12d..2eaa4f03f5 100644 --- a/util/PostgresMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.psql +++ b/util/PostgresMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.psql @@ -1,24 +1,80 @@ --- Update `CollectionUsers` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission -UPDATE "CollectionUsers" cu -SET - "ReadOnly" = false, - "HidePasswords" = false, - "Manage" = true -FROM "OrganizationUser" ou -WHERE cu."OrganizationUserId" = ou."Id" -AND (ou."Type" = 3 OR - (ou."Permissions" IS NOT NULL AND - ((ou."Permissions"::text)::jsonb->>'editAssignedCollections') = 'true')); +-- 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')); --- Insert rows into CollectionUsers for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access -INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage") -SELECT cg."CollectionId", ou."Id", false, false, true -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"); + -- 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; diff --git a/util/PostgresMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.psql b/util/PostgresMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.psql index e69de29bb2..6d22d57833 100644 --- a/util/PostgresMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.psql +++ b/util/PostgresMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.psql @@ -0,0 +1,4 @@ +-- Set "FlexibleCollections" = true for all organizations that have not yet been migrated. +UPDATE "Organization" +SET "FlexibleCollections" = true +WHERE "FlexibleCollections" = false;