Files
server/util/PostgresMigrations/HelperScripts/2024-01-12_00_AccessAllCollectionGroups.psql

Ignoring revisions in .git-blame-ignore-revs. Click here to bypass and see the normal blame view.

48 lines
1.8 KiB
Plaintext
Raw Normal View History

2023-12-20 11:57:36 +00:00
-- Step 1: Create a temporary table to store the groups with AccessAll = 1
CREATE TEMP TABLE IF NOT EXISTS TempGroup AS
2023-12-17 21:26:12 +00:00
SELECT "Id" AS "GroupId", "OrganizationId"
FROM "Group"
WHERE "AccessAll" = true;
2024-01-12 15:33:35 +00:00
-- 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"
2023-12-17 21:26:12 +00:00
UPDATE "CollectionGroups" CG
SET
"ReadOnly" = false,
"HidePasswords" = false,
"Manage" = false
2024-01-12 15:33:35 +00:00
FROM "CollectionGroups" CGUpdate
2023-12-17 21:26:12 +00:00
INNER JOIN "Collection" C ON CGUpdate."CollectionId" = C."Id"
2023-12-20 11:57:36 +00:00
INNER JOIN TempGroup TG ON CGUpdate."GroupId" = TG."GroupId"
2023-12-17 21:26:12 +00:00
WHERE C."OrganizationId" = TG."OrganizationId";
2024-01-12 15:33:35 +00:00
-- Step 4: Insert new rows into "CollectionGroups"
2023-12-17 21:26:12 +00:00
INSERT INTO "CollectionGroups" ("CollectionId", "GroupId", "ReadOnly", "HidePasswords", "Manage")
SELECT C."Id", TG."GroupId", false, false, false
FROM "Collection" C
2023-12-20 11:57:36 +00:00
INNER JOIN TempGroup TG ON C."OrganizationId" = TG."OrganizationId"
LEFT JOIN "CollectionGroups" CG ON CG."CollectionId" = C."Id" AND CG."GroupId" = TG."GroupId"
2023-12-17 21:26:12 +00:00
WHERE CG."CollectionId" IS NULL;
2024-01-12 15:33:35 +00:00
-- Step 5: Update Group to clear AccessAll flag
UPDATE "Group" G
SET "AccessAll" = false, "RevisionDate" = current_timestamp
2024-01-12 15:33:35 +00:00
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
2023-12-17 21:26:12 +00:00
DROP TABLE IF EXISTS TempGroup;
2024-01-12 15:33:35 +00:00
DROP TABLE IF EXISTS TempOrganizationUsers;