From c20912f95c237da671a69eba0e39e5449a1a6d60 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Fri, 29 Mar 2024 12:00:24 +0000 Subject: [PATCH] =?UTF-8?q?[AC-1682]=C2=A0Drop=20temp=20tables=20if=20they?= =?UTF-8?q?=20exist=20when=20starting=20the=20scripts?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- ...22_00_EnableOrgsCollectionEnhancements.sql | 11 +- ...2_00_EnableOrgsCollectionEnhancements.psql | 181 +++++++++--------- ...22_00_EnableOrgsCollectionEnhancements.sql | 9 +- 3 files changed, 105 insertions(+), 96 deletions(-) diff --git a/util/MySqlMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql b/util/MySqlMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql index 2fc43418ca..c70132acc8 100644 --- a/util/MySqlMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql +++ b/util/MySqlMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql @@ -1,6 +1,7 @@ -- Step 1: AccessAll migration for Groups -- Create a temporary table to store the groups with AccessAll = 1 - CREATE TEMPORARY TABLE IF NOT EXISTS `TempGroupsAccessAll` AS + DROP TEMPORARY TABLE IF EXISTS `TempGroupsAccessAll`; + CREATE TEMPORARY TABLE `TempGroupsAccessAll` AS SELECT `G`.`Id` AS `GroupId`, `G`.`OrganizationId` FROM `Group` `G` @@ -9,7 +10,8 @@ -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = 1 - CREATE TEMPORARY TABLE IF NOT EXISTS `TempUsersAccessAll` AS + DROP TEMPORARY TABLE IF EXISTS `TempUsersAccessAll`; + CREATE TEMPORARY TABLE `TempUsersAccessAll` AS SELECT `OU`.`Id` AS `OrganizationUserId`, `OU`.`OrganizationId` FROM `OrganizationUser` `OU` @@ -19,7 +21,8 @@ -- 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 IF NOT EXISTS `TempUserManagers` AS + DROP TEMPORARY TABLE IF EXISTS `TempUserManagers`; + CREATE TEMPORARY TABLE `TempUserManagers` AS SELECT `OU`.`Id` AS `OrganizationUserId`, CASE WHEN `OU`.`Type` = 3 THEN 1 ELSE 0 END AS `IsManager` FROM `OrganizationUser` `OU` @@ -138,7 +141,7 @@ START TRANSACTION; -- Commit transaction COMMIT; --- Step 5: Drop the temporary tables +-- Step 6: Drop the temporary tables DROP TEMPORARY TABLE IF EXISTS `TempGroupsAccessAll`; DROP TEMPORARY TABLE IF EXISTS `TempUsersAccessAll`; DROP TEMPORARY TABLE IF EXISTS `TempUserManagers`; diff --git a/util/PostgresMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.psql b/util/PostgresMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.psql index f837960f3c..ced9098ce0 100644 --- a/util/PostgresMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.psql +++ b/util/PostgresMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.psql @@ -1,6 +1,7 @@ -- Step 1: AccessAll migration for Groups -- Create a temporary table to store the groups with AccessAll = true - CREATE TEMPORARY TABLE IF NOT EXISTS "TempGroupsAccessAll" AS + DROP TABLE IF EXISTS "TempGroupsAccessAll"; + CREATE TEMPORARY TABLE "TempGroupsAccessAll" AS SELECT "G"."Id" AS "GroupId", "G"."OrganizationId" FROM "Group" "G" @@ -9,7 +10,8 @@ -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = true - CREATE TEMPORARY TABLE IF NOT EXISTS "TempUsersAccessAll" AS + DROP TABLE IF EXISTS "TempUsersAccessAll"; + CREATE TEMPORARY TABLE "TempUsersAccessAll" AS SELECT "OU"."Id" AS "OrganizationUserId", "OU"."OrganizationId" FROM "OrganizationUser" "OU" @@ -19,7 +21,8 @@ -- 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 IF NOT EXISTS "TempUserManagers" AS + DROP TABLE IF EXISTS "TempUserManagers"; + CREATE TEMPORARY TABLE "TempUserManagers" AS SELECT "OU"."Id" AS "OrganizationUserId", CASE WHEN "OU"."Type" = 3 THEN true ELSE false END AS "IsManager" FROM "OrganizationUser" "OU" @@ -30,103 +33,103 @@ "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 - FROM "Collection" "C" - WHERE "CG"."CollectionId" = "C"."Id" - AND "C"."OrganizationId" IN (SELECT "OrganizationId" FROM "TempGroupsAccessAll"); +-- Step 1 + -- Update existing rows in CollectionGroups + UPDATE "CollectionGroups" "CG" + SET "ReadOnly" = false, + "HidePasswords" = false, + "Manage" = false + FROM "Collection" "C" + WHERE "CG"."CollectionId" = "C"."Id" + AND "C"."OrganizationId" IN (SELECT "OrganizationId" FROM "TempGroupsAccessAll"); - -- 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; + -- 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"); + -- 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" "target" - SET "ReadOnly" = false, - "HidePasswords" = false, - "Manage" = false - FROM "Collection" "C" - WHERE "target"."CollectionId" = "C"."Id" - AND "C"."OrganizationId" IN (SELECT "OrganizationId" FROM "TempUsersAccessAll") - AND "target"."OrganizationUserId" IN (SELECT "OrganizationUserId" FROM "TempUsersAccessAll"); +-- Step 2 + -- Update existing rows in CollectionUsers + UPDATE "CollectionUsers" "target" + SET "ReadOnly" = false, + "HidePasswords" = false, + "Manage" = false + FROM "Collection" "C" + WHERE "target"."CollectionId" = "C"."Id" + AND "C"."OrganizationId" IN (SELECT "OrganizationId" FROM "TempUsersAccessAll") + AND "target"."OrganizationUserId" IN (SELECT "OrganizationUserId" FROM "TempUsersAccessAll"); - -- 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; + -- 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"); + -- 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"; +-- 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" - ); + -- 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); + -- 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 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 5 + -- Set "FlexibleCollections" = true for all organizations that have not yet been migrated. + UPDATE "Organization" + SET "FlexibleCollections" = true + WHERE "FlexibleCollections" = false; --- Step 5: Drop the temporary tables +-- Step 6: Drop the temporary tables DROP TABLE IF EXISTS "TempGroupsAccessAll"; DROP TABLE IF EXISTS "TempUsersAccessAll"; DROP TABLE IF EXISTS "TempUserManagers"; diff --git a/util/SqliteMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql b/util/SqliteMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql index 8c61687bc5..cd0774ef87 100644 --- a/util/SqliteMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql +++ b/util/SqliteMigrations/HelperScripts/2024-03-22_00_EnableOrgsCollectionEnhancements.sql @@ -1,6 +1,7 @@ -- Step 1: AccessAll migration for Groups -- Create a temporary table to store the groups with AccessAll = 1 - CREATE TEMPORARY TABLE IF NOT EXISTS "TempGroupsAccessAll" AS + DROP TABLE IF EXISTS "TempGroupsAccessAll"; + CREATE TEMPORARY TABLE "TempGroupsAccessAll" AS SELECT "G"."Id" AS "GroupId", "G"."OrganizationId" FROM "Group" "G" @@ -9,7 +10,8 @@ -- Step 2: AccessAll migration for OrganizationUsers -- Create a temporary table to store the OrganizationUsers with AccessAll = 1 - CREATE TEMPORARY TABLE IF NOT EXISTS "TempUsersAccessAll" AS + DROP TABLE IF EXISTS "TempUsersAccessAll"; + CREATE TEMPORARY TABLE "TempUsersAccessAll" AS SELECT "OU"."Id" AS "OrganizationUserId", "OU"."OrganizationId" FROM "OrganizationUser" "OU" @@ -19,7 +21,8 @@ -- 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 IF NOT EXISTS "TempUserManagers" AS + DROP TABLE IF EXISTS "TempUserManagers"; + CREATE TEMPORARY TABLE "TempUserManagers" AS SELECT "OU"."Id" AS "OrganizationUserId", CASE WHEN "OU"."Type" = 3 THEN 1 ELSE 0 END AS "IsManager" FROM "OrganizationUser" "OU"