From 8a0e90c3a12284bb0e5fc8ff57440ad17d2580c7 Mon Sep 17 00:00:00 2001 From: Rui Tome Date: Mon, 15 Jan 2024 16:33:08 +0000 Subject: [PATCH] =?UTF-8?q?[AC-1682]=C2=A0sqlite=20data=20migrations?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- ...024-01-12_00_AccessAllCollectionGroups.sql | 36 ++++-- ...2024-01-12_01_AccessAllCollectionUsers.sql | 42 +++++-- ...02_ManagersEditAssignedCollectionUsers.sql | 109 ++++++++++++++---- ...01-12_03_EnableOrgsFlexibleCollections.sql | 4 + 4 files changed, 151 insertions(+), 40 deletions(-) diff --git a/util/SqliteMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql b/util/SqliteMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql index e228b4fd3a..a40ba2b68b 100644 --- a/util/SqliteMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql +++ b/util/SqliteMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.sql @@ -1,10 +1,16 @@ -- Step 1: Create a temporary table to store the groups with AccessAll = 1 -CREATE TEMPORARY TABLE TempGroup AS +CREATE TEMPORARY TABLE IF NOT EXISTS TempGroup AS SELECT "Id" AS "GroupId", "OrganizationId" FROM "Group" WHERE "AccessAll" = 1; --- Step 2: Update existing rows in "CollectionGroup" +-- Step 2: Create a temporary table to store distinct OrganizationUserIds +CREATE TEMPORARY 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" SET "ReadOnly" = 0, @@ -13,17 +19,33 @@ SET WHERE EXISTS ( SELECT 1 FROM "Collection" C - INNER JOIN TempGroup TG ON "CollectionGroups"."GroupId" = TG."GroupId" + INNER JOIN TempGroup TG ON "CollectionGroups"."GroupId" = TG."GroupId" WHERE "CollectionGroups"."CollectionId" = C."Id" AND 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", 0, 0, 0 FROM "Collection" C - INNER JOIN TempGroup TG ON C."OrganizationId" = TG."OrganizationId" - LEFT JOIN "CollectionGroups" CG ON CG."CollectionId" = C."Id" AND CG."GroupId" = TG."GroupId" +INNER JOIN TempGroup 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; --- Step 4: Drop the temporary table +-- Step 5: Update Group to clear AccessAll flag +UPDATE "Group" +SET "AccessAll" = 0 +WHERE "Id" IN (SELECT "GroupId" FROM TempGroup); + +-- Step 6: Update User AccountRevisionDate for each unique OrganizationUserId +UPDATE "User" +SET "AccountRevisionDate" = CURRENT_TIMESTAMP +WHERE "Id" IN ( + SELECT OU."UserId" + FROM "OrganizationUser" OU + JOIN TempOrganizationUsers TOU ON OU."Id" = TOU."OrganizationUserId" + WHERE OU."Status" = 2 +); + +-- Step 7: Drop the temporary tables DROP TABLE IF EXISTS TempGroup; +DROP TABLE IF EXISTS TempOrganizationUsers; diff --git a/util/SqliteMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql b/util/SqliteMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql index c8c349ef09..fe3ac36ecb 100644 --- a/util/SqliteMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql +++ b/util/SqliteMigrations/HelperScripts/2024-01-12_01_AccessAllCollectionUsers.sql @@ -1,4 +1,10 @@ --- Update existing rows in CollectionUsers +-- Step 1: Create a temporary table +CREATE TEMPORARY TABLE IF NOT EXISTS TempOrgUser AS +SELECT "Id" AS "OrganizationUserId", "OrganizationId" +FROM "OrganizationUser" +WHERE "AccessAll" = 1; + +-- Step 2: Update existing rows in CollectionUsers UPDATE "CollectionUsers" SET "ReadOnly" = 0, @@ -7,18 +13,34 @@ SET WHERE "CollectionId" IN ( SELECT "C"."Id" FROM "Collection" "C" - INNER JOIN "OrganizationUser" "OU" ON "C"."OrganizationId" = "OU"."OrganizationId" - WHERE "OU"."AccessAll" = 1 + INNER JOIN TempOrgUser "OU" ON "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", 0, 0, 0 -FROM "Collection" "C" - INNER JOIN "OrganizationUser" "OU" ON "C"."OrganizationId" = "OU"."OrganizationId" -WHERE "OU"."AccessAll" = 1 - AND NOT EXISTS ( +SELECT C."Id" AS "CollectionId", OU."OrganizationUserId", 0, 0, 0 +FROM "Collection" C +JOIN TempOrgUser OU ON C."OrganizationId" = OU."OrganizationId" +WHERE NOT EXISTS ( SELECT 1 FROM "CollectionUsers" "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" +SET "AccessAll" = 0 +WHERE "Id" IN (SELECT "OrganizationUserId" FROM TempOrgUser); + +-- Step 5: Update "User" AccountRevisionDate for each unique OrganizationUserId +UPDATE "User" +SET "AccountRevisionDate" = CURRENT_TIMESTAMP +WHERE "Id" IN ( + SELECT OU."UserId" + FROM "OrganizationUser" OU + JOIN TempOrgUser TOU ON OU."Id" = TOU."OrganizationUserId" + WHERE OU."Status" = 2 +); + +-- Step 6: Drop the temporary table +DROP TABLE IF EXISTS TempOrgUser; diff --git a/util/SqliteMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql b/util/SqliteMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql index c1f28c1054..fd1c10d23e 100644 --- a/util/SqliteMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql +++ b/util/SqliteMigrations/HelperScripts/2024-01-12_02_ManagersEditAssignedCollectionUsers.sql @@ -1,28 +1,91 @@ --- Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission -UPDATE "CollectionUsers" AS cu -SET - "ReadOnly" = 0, - "HidePasswords" = 0, - "Manage" = 1 -WHERE "OrganizationUserId" IN ( - SELECT ou."Id" - FROM "OrganizationUser" AS ou +-- Step 1: Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission + -- Create a temporary table + CREATE TEMPORARY 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 JSON_VALID(ou."Permissions") > 0 AND JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections') = 'true' - ) -); + ); --- Insert rows to CollectionUser 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", 0, 0, 1 -FROM "CollectionGroups" AS cg - INNER JOIN "GroupUser" AS gu ON cg."GroupId" = gu."GroupId" - INNER JOIN "OrganizationUser" AS ou ON gu."OrganizationUserId" = ou."Id" -WHERE (ou."Type" = 3 OR - (ou."Permissions" IS NOT NULL AND JSON_VALID(ou."Permissions") > 0 AND JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections')) = 'true') - AND NOT EXISTS ( - SELECT 1 FROM "CollectionUsers" AS cu - WHERE cu."CollectionId" = cg."CollectionId" AND cu."OrganizationUserId" = ou."Id" -); + -- Update CollectionUsers with Manage = 1 using the temporary table + UPDATE "CollectionUsers" + SET + "ReadOnly" = 0, + "HidePasswords" = 0, + "Manage" = 1 + WHERE "OrganizationUserId" IN (SELECT "OrganizationUserId" FROM TempOrgUser); + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE "User" + SET "AccountRevisionDate" = CURRENT_TIMESTAMP + WHERE "Id" IN ( + SELECT OU."UserId" + FROM "OrganizationUser" OU + JOIN TempOrgUser TOU ON OU."Id" = TOU."OrganizationUserId" + WHERE OU."Status" = 2 + ); + + -- 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 TEMPORARY TABLE IF NOT EXISTS TempCol AS + SELECT cg."CollectionId", ou."Id" AS "OrganizationUserId" + FROM "CollectionGroups" cg + JOIN "GroupUser" gu ON cg."GroupId" = gu."GroupId" + JOIN "OrganizationUser" ou ON gu."OrganizationUserId" = ou."Id" + WHERE (ou."Type" = 3 OR ( + ou."Permissions" IS NOT NULL AND + JSON_VALID(ou."Permissions") > 0 AND + JSON_EXTRACT(ou."Permissions", '$.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", 0, 0, 1 + FROM TempCol; + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE "User" + SET "AccountRevisionDate" = CURRENT_TIMESTAMP + WHERE "Id" IN ( + SELECT OU."UserId" + FROM "OrganizationUser" OU + JOIN TempCol TC ON TC."OrganizationUserId" = OU."Id" + WHERE OU."Status" = 2 + ); + + -- Drop the temporary table + DROP TABLE IF EXISTS TempCol; + +-- Step 3: Set all Managers to Users + -- Create a temporary table + CREATE TEMPORARY 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" + SET "Type" = 2 + WHERE "Id" IN (SELECT "OrganizationUserId" FROM TempOrgUser); + + -- Update `User` AccountRevisionDate for each unique OrganizationUserId + UPDATE "User" + SET "AccountRevisionDate" = CURRENT_TIMESTAMP + WHERE "Id" IN ( + SELECT OU."UserId" + FROM "OrganizationUser" OU + JOIN TempOrgUser TOU ON TOU."OrganizationUserId" = OU."Id" + WHERE OU."Status" = 2 + ); + + -- Drop the temporary table + DROP TABLE IF EXISTS TempOrgUser; diff --git a/util/SqliteMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql b/util/SqliteMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql index e69de29bb2..f9a41f5969 100644 --- a/util/SqliteMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql +++ b/util/SqliteMigrations/HelperScripts/2024-01-12_03_EnableOrgsFlexibleCollections.sql @@ -0,0 +1,4 @@ +-- Set `FlexibleCollections` = 1 for all organizations that have not yet been migrated. +UPDATE "Organization" +SET "FlexibleCollections" = 1 +WHERE "FlexibleCollections" = 0;