1
0
mirror of https://github.com/bitwarden/server.git synced 2024-11-25 12:45:18 +01:00
bitwarden-server/util/Migrator/DbScripts/2024-07-24_00_OrganizationUserMakeAccessAllOptional.sql

449 lines
12 KiB
Transact-SQL

-- Remove OrganizationUser.AccessAll from all sprocs that read/write it directly
-- View: don't return the AccessAll value. This is already unused in code.
CREATE OR ALTER VIEW [dbo].[OrganizationUserUserDetailsView]
AS
SELECT
OU.[Id],
OU.[UserId],
OU.[OrganizationId],
U.[Name],
ISNULL(U.[Email], OU.[Email]) Email,
U.[AvatarColor],
U.[TwoFactorProviders],
U.[Premium],
OU.[Status],
OU.[Type],
OU.[AccessSecretsManager],
OU.[ExternalId],
SU.[ExternalId] SsoExternalId,
OU.[Permissions],
OU.[ResetPasswordKey],
U.[UsesKeyConnector],
CASE WHEN U.[MasterPassword] IS NOT NULL THEN 1 ELSE 0 END AS HasMasterPassword
FROM
[dbo].[OrganizationUser] OU
LEFT JOIN
[dbo].[User] U ON U.[Id] = OU.[UserId]
LEFT JOIN
[dbo].[SsoUser] SU ON SU.[UserId] = OU.[UserId] AND SU.[OrganizationId] = OU.[OrganizationId]
GO
-- Refresh metadata on sprocs that use the View
IF OBJECT_ID('[dbo].[OrganizationUser_ReadByMinimumRole]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[OrganizationUser_ReadByMinimumRole]';
END
GO
IF OBJECT_ID('[dbo].[OrganizationUserUserDetails_ReadById]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[OrganizationUserUserDetails_ReadById]';
END
GO
IF OBJECT_ID('[dbo].[OrganizationUserUserDetails_ReadByOrganizationId]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[OrganizationUserUserDetails_ReadByOrganizationId]';
END
GO
IF OBJECT_ID('[dbo].[OrganizationUser_ReadWithCollectionsById]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[OrganizationUser_ReadWithCollectionsById]';
END
GO
-- Sprocs that don't use user-defined types: Give AccessAll a default value so we can remove it from the code
-- before dropping it permanently from the db
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_Create]
@Id UNIQUEIDENTIFIER OUTPUT,
@OrganizationId UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@Email NVARCHAR(256),
@Key VARCHAR(MAX),
@Status SMALLINT,
@Type TINYINT,
@AccessAll BIT = 0,
@ExternalId NVARCHAR(300),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@Permissions NVARCHAR(MAX),
@ResetPasswordKey VARCHAR(MAX),
@AccessSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
INSERT INTO [dbo].[OrganizationUser]
(
[Id],
[OrganizationId],
[UserId],
[Email],
[Key],
[Status],
[Type],
[AccessAll],
[ExternalId],
[CreationDate],
[RevisionDate],
[Permissions],
[ResetPasswordKey],
[AccessSecretsManager]
)
VALUES
(
@Id,
@OrganizationId,
@UserId,
@Email,
@Key,
@Status,
@Type,
@AccessAll,
@ExternalId,
@CreationDate,
@RevisionDate,
@Permissions,
@ResetPasswordKey,
@AccessSecretsManager
)
END
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_CreateWithCollections]
@Id UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@Email NVARCHAR(256),
@Key VARCHAR(MAX),
@Status SMALLINT,
@Type TINYINT,
@AccessAll BIT = 0,
@ExternalId NVARCHAR(300),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@Permissions NVARCHAR(MAX),
@ResetPasswordKey VARCHAR(MAX),
@Collections AS [dbo].[CollectionAccessSelectionType] READONLY,
@AccessSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[OrganizationUser_Create] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager
;WITH [AvailableCollectionsCTE] AS(
SELECT
[Id]
FROM
[dbo].[Collection]
WHERE
[OrganizationId] = @OrganizationId
)
INSERT INTO [dbo].[CollectionUser]
(
[CollectionId],
[OrganizationUserId],
[ReadOnly],
[HidePasswords],
[Manage]
)
SELECT
[Id],
@Id,
[ReadOnly],
[HidePasswords],
[Manage]
FROM
@Collections
WHERE
[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE])
END
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_Update]
@Id UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@Email NVARCHAR(256),
@Key VARCHAR(MAX),
@Status SMALLINT,
@Type TINYINT,
@AccessAll BIT = 0,
@ExternalId NVARCHAR(300),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@Permissions NVARCHAR(MAX),
@ResetPasswordKey VARCHAR(MAX),
@AccessSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
UPDATE
[dbo].[OrganizationUser]
SET
[OrganizationId] = @OrganizationId,
[UserId] = @UserId,
[Email] = @Email,
[Key] = @Key,
[Status] = @Status,
[Type] = @Type,
[AccessAll] = @AccessAll,
[ExternalId] = @ExternalId,
[CreationDate] = @CreationDate,
[RevisionDate] = @RevisionDate,
[Permissions] = @Permissions,
[ResetPasswordKey] = @ResetPasswordKey,
[AccessSecretsManager] = @AccessSecretsManager
WHERE
[Id] = @Id
EXEC [dbo].[User_BumpAccountRevisionDate] @UserId
END
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections]
@Id UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@Email NVARCHAR(256),
@Key VARCHAR(MAX),
@Status SMALLINT,
@Type TINYINT,
@AccessAll BIT = 0,
@ExternalId NVARCHAR(300),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@Permissions NVARCHAR(MAX),
@ResetPasswordKey VARCHAR(MAX),
@Collections AS [dbo].[CollectionAccessSelectionType] READONLY,
@AccessSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate, @Permissions, @ResetPasswordKey, @AccessSecretsManager
-- Update
UPDATE
[Target]
SET
[Target].[ReadOnly] = [Source].[ReadOnly],
[Target].[HidePasswords] = [Source].[HidePasswords],
[Target].[Manage] = [Source].[Manage]
FROM
[dbo].[CollectionUser] AS [Target]
INNER JOIN
@Collections AS [Source] ON [Source].[Id] = [Target].[CollectionId]
WHERE
[Target].[OrganizationUserId] = @Id
AND (
[Target].[ReadOnly] != [Source].[ReadOnly]
OR [Target].[HidePasswords] != [Source].[HidePasswords]
OR [Target].[Manage] != [Source].[Manage]
)
-- Insert
INSERT INTO [dbo].[CollectionUser]
(
[CollectionId],
[OrganizationUserId],
[ReadOnly],
[HidePasswords],
[Manage]
)
SELECT
[Source].[Id],
@Id,
[Source].[ReadOnly],
[Source].[HidePasswords],
[Source].[Manage]
FROM
@Collections AS [Source]
INNER JOIN
[dbo].[Collection] C ON C.[Id] = [Source].[Id] AND C.[OrganizationId] = @OrganizationId
WHERE
NOT EXISTS (
SELECT
1
FROM
[dbo].[CollectionUser]
WHERE
[CollectionId] = [Source].[Id]
AND [OrganizationUserId] = @Id
)
-- Delete
DELETE
CU
FROM
[dbo].[CollectionUser] CU
WHERE
CU.[OrganizationUserId] = @Id
AND NOT EXISTS (
SELECT
1
FROM
@Collections
WHERE
[Id] = CU.[CollectionId]
)
END
GO
-- Sprocs that do use user-defined types:
-- Create a new version of the sproc without using the type, and update that.
-- These were already versioned from a previous update, so take the opportunity to drop the version suffix.
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_CreateMany]
@jsonData NVARCHAR(MAX)
AS
BEGIN
SET NOCOUNT ON
INSERT INTO [dbo].[OrganizationUser]
(
[Id],
[OrganizationId],
[UserId],
[Email],
[Key],
[Status],
[Type],
[AccessAll],
[ExternalId],
[CreationDate],
[RevisionDate],
[Permissions],
[ResetPasswordKey],
[AccessSecretsManager]
)
SELECT
OUI.[Id],
OUI.[OrganizationId],
OUI.[UserId],
OUI.[Email],
OUI.[Key],
OUI.[Status],
OUI.[Type],
0, -- AccessAll will be removed shortly
OUI.[ExternalId],
OUI.[CreationDate],
OUI.[RevisionDate],
OUI.[Permissions],
OUI.[ResetPasswordKey],
OUI.[AccessSecretsManager]
FROM
OPENJSON(@jsonData)
WITH (
[Id] UNIQUEIDENTIFIER '$.Id',
[OrganizationId] UNIQUEIDENTIFIER '$.OrganizationId',
[UserId] UNIQUEIDENTIFIER '$.UserId',
[Email] NVARCHAR(256) '$.Email',
[Key] VARCHAR(MAX) '$.Key',
[Status] SMALLINT '$.Status',
[Type] TINYINT '$.Type',
[ExternalId] NVARCHAR(300) '$.ExternalId',
[CreationDate] DATETIME2(7) '$.CreationDate',
[RevisionDate] DATETIME2(7) '$.RevisionDate',
[Permissions] NVARCHAR (MAX) '$.Permissions',
[ResetPasswordKey] VARCHAR (MAX) '$.ResetPasswordKey',
[AccessSecretsManager] BIT '$.AccessSecretsManager'
) OUI
END
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_UpdateMany]
@jsonData NVARCHAR(MAX)
AS
BEGIN
SET NOCOUNT ON
-- Parse the JSON string
DECLARE @OrganizationUserInput AS TABLE (
[Id] UNIQUEIDENTIFIER,
[OrganizationId] UNIQUEIDENTIFIER,
[UserId] UNIQUEIDENTIFIER,
[Email] NVARCHAR(256),
[Key] VARCHAR(MAX),
[Status] SMALLINT,
[Type] TINYINT,
[ExternalId] NVARCHAR(300),
[CreationDate] DATETIME2(7),
[RevisionDate] DATETIME2(7),
[Permissions] NVARCHAR(MAX),
[ResetPasswordKey] VARCHAR(MAX),
[AccessSecretsManager] BIT
)
INSERT INTO @OrganizationUserInput
SELECT
[Id],
[OrganizationId],
[UserId],
[Email],
[Key],
[Status],
[Type],
[ExternalId],
[CreationDate],
[RevisionDate],
[Permissions],
[ResetPasswordKey],
[AccessSecretsManager]
FROM OPENJSON(@jsonData)
WITH (
[Id] UNIQUEIDENTIFIER '$.Id',
[OrganizationId] UNIQUEIDENTIFIER '$.OrganizationId',
[UserId] UNIQUEIDENTIFIER '$.UserId',
[Email] NVARCHAR(256) '$.Email',
[Key] VARCHAR(MAX) '$.Key',
[Status] SMALLINT '$.Status',
[Type] TINYINT '$.Type',
[ExternalId] NVARCHAR(300) '$.ExternalId',
[CreationDate] DATETIME2(7) '$.CreationDate',
[RevisionDate] DATETIME2(7) '$.RevisionDate',
[Permissions] NVARCHAR (MAX) '$.Permissions',
[ResetPasswordKey] VARCHAR (MAX) '$.ResetPasswordKey',
[AccessSecretsManager] BIT '$.AccessSecretsManager'
)
-- Perform the update
UPDATE
OU
SET
[OrganizationId] = OUI.[OrganizationId],
[UserId] = OUI.[UserId],
[Email] = OUI.[Email],
[Key] = OUI.[Key],
[Status] = OUI.[Status],
[Type] = OUI.[Type],
[AccessAll] = 0, -- AccessAll will be removed shortly
[ExternalId] = OUI.[ExternalId],
[CreationDate] = OUI.[CreationDate],
[RevisionDate] = OUI.[RevisionDate],
[Permissions] = OUI.[Permissions],
[ResetPasswordKey] = OUI.[ResetPasswordKey],
[AccessSecretsManager] = OUI.[AccessSecretsManager]
FROM
[dbo].[OrganizationUser] OU
INNER JOIN
@OrganizationUserInput OUI ON OU.Id = OUI.Id
-- Bump account revision dates
EXEC [dbo].[User_BumpManyAccountRevisionDates]
(
SELECT [UserId]
FROM @OrganizationUserInput
)
END
GO