mirror of
https://github.com/bitwarden/server.git
synced 2025-07-01 16:12:49 -05:00
[AC-1682] sqlite data migrations
This commit is contained in:
@ -1,10 +1,16 @@
|
|||||||
-- Step 1: Create a temporary table to store the groups with AccessAll = 1
|
-- 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"
|
SELECT "Id" AS "GroupId", "OrganizationId"
|
||||||
FROM "Group"
|
FROM "Group"
|
||||||
WHERE "AccessAll" = 1;
|
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"
|
UPDATE "CollectionGroups"
|
||||||
SET
|
SET
|
||||||
"ReadOnly" = 0,
|
"ReadOnly" = 0,
|
||||||
@ -13,17 +19,33 @@ SET
|
|||||||
WHERE EXISTS (
|
WHERE EXISTS (
|
||||||
SELECT 1
|
SELECT 1
|
||||||
FROM "Collection" C
|
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"
|
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")
|
INSERT INTO "CollectionGroups" ("CollectionId", "GroupId", "ReadOnly", "HidePasswords", "Manage")
|
||||||
SELECT C."Id", TG."GroupId", 0, 0, 0
|
SELECT C."Id", TG."GroupId", 0, 0, 0
|
||||||
FROM "Collection" C
|
FROM "Collection" C
|
||||||
INNER JOIN TempGroup TG ON C."OrganizationId" = TG."OrganizationId"
|
INNER JOIN TempGroup TG ON C."OrganizationId" = TG."OrganizationId"
|
||||||
LEFT JOIN "CollectionGroups" CG ON CG."CollectionId" = C."Id" AND CG."GroupId" = TG."GroupId"
|
LEFT JOIN "CollectionGroups" CG ON C."Id" = CG."CollectionId" AND TG."GroupId" = CG."GroupId"
|
||||||
WHERE CG."CollectionId" IS NULL;
|
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 TempGroup;
|
||||||
|
DROP TABLE IF EXISTS TempOrganizationUsers;
|
||||||
|
@ -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"
|
UPDATE "CollectionUsers"
|
||||||
SET
|
SET
|
||||||
"ReadOnly" = 0,
|
"ReadOnly" = 0,
|
||||||
@ -7,18 +13,34 @@ SET
|
|||||||
WHERE "CollectionId" IN (
|
WHERE "CollectionId" IN (
|
||||||
SELECT "C"."Id"
|
SELECT "C"."Id"
|
||||||
FROM "Collection" "C"
|
FROM "Collection" "C"
|
||||||
INNER JOIN "OrganizationUser" "OU" ON "C"."OrganizationId" = "OU"."OrganizationId"
|
INNER JOIN TempOrgUser "OU" ON "C"."OrganizationId" = "OU"."OrganizationId"
|
||||||
WHERE "OU"."AccessAll" = 1
|
|
||||||
);
|
);
|
||||||
|
|
||||||
-- Insert new rows into CollectionUsers
|
-- Step 3: Insert new rows into CollectionUsers
|
||||||
INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage")
|
INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage")
|
||||||
SELECT "C"."Id" AS "CollectionId", "OU"."Id" AS "OrganizationUserId", 0, 0, 0
|
SELECT C."Id" AS "CollectionId", OU."OrganizationUserId", 0, 0, 0
|
||||||
FROM "Collection" "C"
|
FROM "Collection" C
|
||||||
INNER JOIN "OrganizationUser" "OU" ON "C"."OrganizationId" = "OU"."OrganizationId"
|
JOIN TempOrgUser OU ON C."OrganizationId" = OU."OrganizationId"
|
||||||
WHERE "OU"."AccessAll" = 1
|
WHERE NOT EXISTS (
|
||||||
AND NOT EXISTS (
|
|
||||||
SELECT 1
|
SELECT 1
|
||||||
FROM "CollectionUsers" "CU"
|
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;
|
||||||
|
@ -1,28 +1,91 @@
|
|||||||
-- Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission
|
-- Step 1: Update `CollectionUser` with `Manage` = 1 for all users with Manager role or 'EditAssignedCollections' permission
|
||||||
UPDATE "CollectionUsers" AS cu
|
-- Create a temporary table
|
||||||
SET
|
CREATE TEMPORARY TABLE IF NOT EXISTS TempOrgUser AS
|
||||||
"ReadOnly" = 0,
|
SELECT ou."Id" AS "OrganizationUserId"
|
||||||
"HidePasswords" = 0,
|
FROM "OrganizationUser" ou
|
||||||
"Manage" = 1
|
|
||||||
WHERE "OrganizationUserId" IN (
|
|
||||||
SELECT ou."Id"
|
|
||||||
FROM "OrganizationUser" AS ou
|
|
||||||
WHERE ou."Type" = 3 OR (
|
WHERE ou."Type" = 3 OR (
|
||||||
ou."Permissions" IS NOT NULL AND
|
ou."Permissions" IS NOT NULL AND
|
||||||
JSON_VALID(ou."Permissions") > 0 AND
|
JSON_VALID(ou."Permissions") > 0 AND
|
||||||
JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections') = 'true'
|
JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections') = 'true'
|
||||||
)
|
);
|
||||||
);
|
|
||||||
|
|
||||||
-- Insert rows to CollectionUser for Managers and users with 'EditAssignedCollections' permission assigned to groups with collection access
|
-- Update CollectionUsers with Manage = 1 using the temporary table
|
||||||
INSERT INTO "CollectionUsers" ("CollectionId", "OrganizationUserId", "ReadOnly", "HidePasswords", "Manage")
|
UPDATE "CollectionUsers"
|
||||||
SELECT cg."CollectionId", ou."Id", 0, 0, 1
|
SET
|
||||||
FROM "CollectionGroups" AS cg
|
"ReadOnly" = 0,
|
||||||
INNER JOIN "GroupUser" AS gu ON cg."GroupId" = gu."GroupId"
|
"HidePasswords" = 0,
|
||||||
INNER JOIN "OrganizationUser" AS ou ON gu."OrganizationUserId" = ou."Id"
|
"Manage" = 1
|
||||||
WHERE (ou."Type" = 3 OR
|
WHERE "OrganizationUserId" IN (SELECT "OrganizationUserId" FROM TempOrgUser);
|
||||||
(ou."Permissions" IS NOT NULL AND JSON_VALID(ou."Permissions") > 0 AND JSON_EXTRACT(ou."Permissions", '$.editAssignedCollections')) = 'true')
|
|
||||||
AND NOT EXISTS (
|
-- Update `User` AccountRevisionDate for each unique OrganizationUserId
|
||||||
SELECT 1 FROM "CollectionUsers" AS cu
|
UPDATE "User"
|
||||||
WHERE cu."CollectionId" = cg."CollectionId" AND cu."OrganizationUserId" = ou."Id"
|
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;
|
||||||
|
@ -0,0 +1,4 @@
|
|||||||
|
-- Set `FlexibleCollections` = 1 for all organizations that have not yet been migrated.
|
||||||
|
UPDATE "Organization"
|
||||||
|
SET "FlexibleCollections" = 1
|
||||||
|
WHERE "FlexibleCollections" = 0;
|
||||||
|
Reference in New Issue
Block a user