1
0
mirror of https://github.com/bitwarden/server.git synced 2024-12-05 14:23:30 +01:00
bitwarden-server/util/SqliteMigrations/HelperScripts/2024-04-25_00_EnableOrgsCollectionEnhancements.sql
Rui Tomé b3e5076128
[AC-1978] Flexible collections: EF data migrations for deprecated permissions (#3969)
* [AC-1682] Added MySql migration and script

(cherry picked from commit d367f6de6b)

* [AC-1682] Added Postgres migration and script

(cherry picked from commit 9bde1604da)

* [AC-1682] Added Sqlite migration and script

(cherry picked from commit 262887f9c3)

* [AC-1682] dotnet format

(cherry picked from commit 00eea0621c)

* [AC-1682] Fixed Sqlite query

(cherry picked from commit 26f5bf8afd)

* [AC-1682] Drop temp tables if they exist when starting the scripts

(cherry picked from commit c20912f95c)

* [AC-1682] Removed MySql transaction from script because EF migration already wraps it under its own transaction

(cherry picked from commit 7b54d78d67)

* [AC-1682] Setting FlexibleCollections = 1 only for Orgs that had data migrated in previous steps

(cherry picked from commit 28bba94d81)

* [AC-1682] Updated queries to check for OrganizationId

(cherry picked from commit a957530d5e)

* [AC-1682] Fixed MySql script

(cherry picked from commit deee483ab7)

* [AC-1682] Fixed Postgres query

(cherry picked from commit c3ca9ec3c8)

* [AC-1682] Fix Sqlite query

(cherry picked from commit fada0a81bf)

* [AC-1682] Reverted scripts back to enabling Flexible Collections to all existing Orgs

(cherry picked from commit bd3b21b969)

* [AC-1682] Removed dropping temporary table from scripts

(cherry picked from commit eb7794d592)

* [AC-1682] Removed other temp table drops

(cherry picked from commit 26768b7bf8)

* [AC-1978] Fix issue that allows the web app to have the user type Manager available

(cherry picked from commit 2890f78870)

* [AC-1682] Bump dates on migration scripts

---------

Co-authored-by: Thomas Rittson <31796059+eliykat@users.noreply.github.com>
2024-04-26 14:11:29 +01:00

152 lines
6.6 KiB
SQL

-- Step 1: AccessAll migration for Groups
-- Create a temporary table to store the groups with AccessAll = 1
CREATE TEMPORARY TABLE "TempGroupsAccessAll" AS
SELECT "G"."Id" AS "GroupId",
"G"."OrganizationId"
FROM "Group" "G"
INNER JOIN "Organization" "O" ON "G"."OrganizationId" = "O"."Id"
WHERE "O"."FlexibleCollections" = 0 AND "G"."AccessAll" = 1;
-- Step 2: AccessAll migration for OrganizationUsers
-- Create a temporary table to store the OrganizationUsers with AccessAll = 1
CREATE TEMPORARY TABLE "TempUsersAccessAll" AS
SELECT "OU"."Id" AS "OrganizationUserId",
"OU"."OrganizationId"
FROM "OrganizationUser" "OU"
INNER JOIN "Organization" "O" ON "OU"."OrganizationId" = "O"."Id"
WHERE "O"."FlexibleCollections" = 0 AND "OU"."AccessAll" = 1;
-- 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 "TempUserManagers" AS
SELECT "OU"."Id" AS "OrganizationUserId",
"OU"."OrganizationId",
CASE WHEN "OU"."Type" = 3 THEN 1 ELSE 0 END AS "IsManager"
FROM "OrganizationUser" "OU"
INNER JOIN "Organization" "O" ON "OU"."OrganizationId" = "O"."Id"
WHERE "O"."FlexibleCollections" = 0 AND
("OU"."Type" = 3 OR
("OU"."Type" = 4 AND
"OU"."Permissions" IS NOT NULL AND
JSON_VALID("OU"."Permissions") AND JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections') = 1));
-- Step 1
-- Update existing rows in "CollectionGroups"
UPDATE "CollectionGroups"
SET
"ReadOnly" = 0,
"HidePasswords" = 0,
"Manage" = 0
WHERE EXISTS (
SELECT 1
FROM "Collection" "C"
INNER JOIN "TempGroupsAccessAll" "TG" ON "CollectionGroups"."GroupId" = "TG"."GroupId"
WHERE "CollectionGroups"."CollectionId" = "C"."Id" AND C."OrganizationId" = "TG"."OrganizationId"
);
-- 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 "TempGroupsAccessAll" "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;
-- Update "Group" to clear "AccessAll" flag and update "RevisionDate"
UPDATE "Group"
SET "AccessAll" = 0, "RevisionDate" = CURRENT_TIMESTAMP
WHERE "Id" IN (SELECT "GroupId" FROM "TempGroupsAccessAll");
-- Step 2
-- Update existing rows in "CollectionUsers"
UPDATE "CollectionUsers"
SET "ReadOnly" = 0,
"HidePasswords" = 0,
"Manage" = 0
WHERE EXISTS (
SELECT 1
FROM "Collection" AS "C"
INNER JOIN "TempUsersAccessAll" AS "TU" ON "CollectionUsers"."OrganizationUserId" = "TU"."OrganizationUserId" AND
"C"."OrganizationId" = "TU"."OrganizationId"
WHERE "CollectionUsers"."CollectionId" = "C"."Id"
);
-- Insert new rows into "CollectionUsers"
INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage")
SELECT "C"."Id", "TU"."OrganizationUserId", 0, 0, 0
FROM "Collection" "C"
INNER JOIN "TempUsersAccessAll" "TU" ON "C"."OrganizationId" = "TU"."OrganizationId"
LEFT JOIN "CollectionUsers" "target"
ON "target"."CollectionId" = "C"."Id" AND "target"."OrganizationUserId" = "TU"."OrganizationUserId"
WHERE "target"."CollectionId" IS NULL;
-- Update "OrganizationUser" to clear "AccessAll" flag
UPDATE "OrganizationUser"
SET "AccessAll" = 0, "RevisionDate" = CURRENT_TIMESTAMP
WHERE "Id" IN (SELECT "OrganizationUserId" FROM "TempUsersAccessAll");
-- Step 3
-- Update "CollectionUsers" with "Manage" = 1 using the temporary table
UPDATE "CollectionUsers"
SET
"ReadOnly" = 0,
"HidePasswords" = 0,
"Manage" = 1
WHERE "OrganizationUserId" IN (SELECT "OrganizationUserId" FROM "TempUserManagers");
-- Insert rows to "CollectionUsers" with "Manage" = 1 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", 0, 0, 1
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"
SET "Type" = 2, "RevisionDate" = CURRENT_TIMESTAMP -- User
WHERE "Id" IN (SELECT "OrganizationUserId" FROM "TempUserManagers" WHERE "IsManager" = 1);
-- Step 4
-- Update "User" "AccountRevisionDate" for each unique "OrganizationUserId"
UPDATE "User"
SET "AccountRevisionDate" = CURRENT_TIMESTAMP
WHERE "Id" IN (
SELECT DISTINCT "OU"."UserId"
FROM "OrganizationUser" "OU"
INNER JOIN (
-- Step 1
SELECT "GU"."OrganizationUserId"
FROM "GroupUser" "GU"
INNER JOIN "TempGroupsAccessAll" "TG" ON "GU"."GroupId" = "TG"."GroupId"
UNION
-- Step 2
SELECT "OrganizationUserId"
FROM "TempUsersAccessAll"
UNION
-- Step 3
SELECT "OrganizationUserId"
FROM "TempUserManagers"
) AS "CombinedOrgUsers" ON "OU"."Id" = "CombinedOrgUsers"."OrganizationUserId"
);
-- Step 5: Set "FlexibleCollections" = 1 for all organizations that have not yet been migrated.
UPDATE "Organization"
SET "FlexibleCollections" = 1
WHERE "FlexibleCollections" = 0;
-- Step 6: Drop the temporary tables
DROP TABLE IF EXISTS "TempGroupsAccessAll";
DROP TABLE IF EXISTS "TempUsersAccessAll";
DROP TABLE IF EXISTS "TempUserManagers";