1
0
mirror of https://github.com/bitwarden/server.git synced 2024-11-29 13:25:17 +01:00
bitwarden-server/util/Migrator/DbScripts/2023-09-27_00_CipherKeyUpdate.sql
Todd Martin 7ede956c32
Individual Vault Item Encryption Feature (#3256)
* [SG-966] [SG-967] Add new cipher properties, update DB objects and create migrations (#2681)

* Updated cipher entity with two new columns

* Added sqlserver mifgration and updated applicable stored procedures and table

* Added EF Migrations

* Made changes to response model to include new column properties

* Fixed formatting

* Modified scripts to reflect suggestions made on PR

* Added column to cipher table using default

* Include constraint in create cipher table script

* Added key and forcerotatekey property to request model (#2716)

* Added key update on the Cipher_UpdateWithCollection stored procedure, ef (#2855)

* Added key and forceKeyRotation to BuildCiphersTable method (#2893)

* [PM-2211] Remove forceKeyRotation column (#2921)

* Removed forceKeyRotation column

* Adjusted date for migrtaion file

* Passed key column to update cipher script to update cipher key when it is rotated (#2967)

* [PM-2448] Update CipherDetails_Update SP to update attachment column (#2992)

* Updated the cipherdetails_update stored procedure to update the attachement column when encrypted with the cipher key

* Moved migration and renamed old migration file

* Fixed lint issues

* Fixed lint issues

* renamed sqlserver migration to have a more recent date

* [PM-2548] Added validation to edit and add attachments methods (#3130)

* PM-2548 Added validation to edit and add attachments methods

* PM-2548 Moved the validation to a private method

* PM-2548 Minor refactor

* Bumped up minimum version

* Bumped up minimum version

* Changed version for tests purposes

* Bumped up minimum version

* Updated encryption minimum version to match clients for QA.

* PM-3976 Passed Key column to update cipher on bulk edit (#3299)

* Updated minimum client version in preparation for release.

* Renamed migration with current date. (#3303)

---------

Co-authored-by: SmithThe4th <gsmith@bitwarden.com>
Co-authored-by: gbubemismith <gsmithwalter@gmail.com>
Co-authored-by: Carlos Gonçalves <cgoncalves@bitwarden.com>
Co-authored-by: Carlos Gonçalves <carlosmaccam@gmail.com>
2023-09-28 08:45:13 -04:00

429 lines
11 KiB
Transact-SQL

-- Add Key Column
IF COL_LENGTH('[dbo].[Cipher]', 'Key') IS NULL
BEGIN
ALTER TABLE [dbo].[Cipher] ADD [Key] VARCHAR (MAX) NULL;
END
GO
-- Remove ForceKeyRotation Column from the Cipher table
-- (this is to help with the dev work as the column was no longer needed)
IF COL_LENGTH('[dbo].[Cipher]', 'ForceKeyRotation') IS NOT NULL
BEGIN
ALTER TABLE [dbo].[Cipher] DROP CONSTRAINT [D_Cipher_ForceKeyRotation];
ALTER TABLE [dbo].[Cipher] DROP COLUMN [ForceKeyRotation];
END
GO
CREATE OR ALTER FUNCTION [dbo].[CipherDetails](@UserId UNIQUEIDENTIFIER)
RETURNS TABLE
AS RETURN
SELECT
C.[Id],
C.[UserId],
C.[OrganizationId],
C.[Type],
C.[Data],
C.[Attachments],
C.[CreationDate],
C.[RevisionDate],
CASE
WHEN
@UserId IS NULL
OR C.[Favorites] IS NULL
OR JSON_VALUE(C.[Favorites], CONCAT('$."', @UserId, '"')) IS NULL
THEN 0
ELSE 1
END [Favorite],
CASE
WHEN
@UserId IS NULL
OR C.[Folders] IS NULL
THEN NULL
ELSE TRY_CONVERT(UNIQUEIDENTIFIER, JSON_VALUE(C.[Folders], CONCAT('$."', @UserId, '"')))
END [FolderId],
C.[DeletedDate],
C.[Reprompt],
C.[Key]
FROM
[dbo].[Cipher] C
GO
IF OBJECT_ID('[dbo].[UserCipherDetails]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[UserCipherDetails]';
END
GO
IF OBJECT_ID('[dbo].[CipherView]') IS NOT NULL
BEGIN
EXECUTE sp_refreshsqlmodule N'[dbo].[CipherView]';
END
GO
CREATE OR ALTER PROCEDURE [dbo].[CipherDetails_Create]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX), -- not used
@Folders NVARCHAR(MAX), -- not used
@Attachments NVARCHAR(MAX), -- not used
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@FolderId UNIQUEIDENTIFIER,
@Favorite BIT,
@Edit BIT, -- not used
@ViewPassword BIT, -- not used
@OrganizationUseTotp BIT, -- not used
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL
AS
BEGIN
SET NOCOUNT ON
DECLARE @UserIdKey VARCHAR(50) = CONCAT('"', @UserId, '"')
DECLARE @UserIdPath VARCHAR(50) = CONCAT('$.', @UserIdKey)
INSERT INTO [dbo].[Cipher]
(
[Id],
[UserId],
[OrganizationId],
[Type],
[Data],
[Favorites],
[Folders],
[CreationDate],
[RevisionDate],
[DeletedDate],
[Reprompt],
[Key]
)
VALUES
(
@Id,
CASE WHEN @OrganizationId IS NULL THEN @UserId ELSE NULL END,
@OrganizationId,
@Type,
@Data,
CASE WHEN @Favorite = 1 THEN CONCAT('{', @UserIdKey, ':true}') ELSE NULL END,
CASE WHEN @FolderId IS NOT NULL THEN CONCAT('{', @UserIdKey, ':"', @FolderId, '"', '}') ELSE NULL END,
@CreationDate,
@RevisionDate,
@DeletedDate,
@Reprompt,
@Key
)
IF @OrganizationId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId
END
ELSE IF @UserId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDate] @UserId
END
END
GO
CREATE OR ALTER PROCEDURE [dbo].[CipherDetails_Update]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX), -- not used
@Folders NVARCHAR(MAX), -- not used
@Attachments NVARCHAR(MAX),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@FolderId UNIQUEIDENTIFIER,
@Favorite BIT,
@Edit BIT, -- not used
@ViewPassword BIT, -- not used
@OrganizationUseTotp BIT, -- not used
@DeletedDate DATETIME2(2),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL
AS
BEGIN
SET NOCOUNT ON
DECLARE @UserIdKey VARCHAR(50) = CONCAT('"', @UserId, '"')
DECLARE @UserIdPath VARCHAR(50) = CONCAT('$.', @UserIdKey)
UPDATE
[dbo].[Cipher]
SET
[UserId] = CASE WHEN @OrganizationId IS NULL THEN @UserId ELSE NULL END,
[OrganizationId] = @OrganizationId,
[Type] = @Type,
[Data] = @Data,
[Folders] =
CASE
WHEN @FolderId IS NOT NULL AND [Folders] IS NULL THEN
CONCAT('{', @UserIdKey, ':"', @FolderId, '"', '}')
WHEN @FolderId IS NOT NULL THEN
JSON_MODIFY([Folders], @UserIdPath, CAST(@FolderId AS VARCHAR(50)))
ELSE
JSON_MODIFY([Folders], @UserIdPath, NULL)
END,
[Favorites] =
CASE
WHEN @Favorite = 1 AND [Favorites] IS NULL THEN
CONCAT('{', @UserIdKey, ':true}')
WHEN @Favorite = 1 THEN
JSON_MODIFY([Favorites], @UserIdPath, CAST(1 AS BIT))
ELSE
JSON_MODIFY([Favorites], @UserIdPath, NULL)
END,
[Attachments] = @Attachments,
[Reprompt] = @Reprompt,
[CreationDate] = @CreationDate,
[RevisionDate] = @RevisionDate,
[DeletedDate] = @DeletedDate,
[Key] = @Key
WHERE
[Id] = @Id
IF @OrganizationId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId
END
ELSE IF @UserId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDate] @UserId
END
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Cipher_Update]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX),
@Folders NVARCHAR(MAX),
@Attachments NVARCHAR(MAX),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL
AS
BEGIN
SET NOCOUNT ON
UPDATE
[dbo].[Cipher]
SET
[UserId] = CASE WHEN @OrganizationId IS NULL THEN @UserId ELSE NULL END,
[OrganizationId] = @OrganizationId,
[Type] = @Type,
[Data] = @Data,
[Favorites] = @Favorites,
[Folders] = @Folders,
[Attachments] = @Attachments,
[CreationDate] = @CreationDate,
[RevisionDate] = @RevisionDate,
[DeletedDate] = @DeletedDate,
[Reprompt] = @Reprompt,
[Key] = @Key
WHERE
[Id] = @Id
IF @OrganizationId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId
END
ELSE IF @UserId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDate] @UserId
END
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Cipher_Create]
@Id UNIQUEIDENTIFIER OUTPUT,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX),
@Folders NVARCHAR(MAX),
@Attachments NVARCHAR(MAX),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL
AS
BEGIN
SET NOCOUNT ON
INSERT INTO [dbo].[Cipher]
(
[Id],
[UserId],
[OrganizationId],
[Type],
[Data],
[Favorites],
[Folders],
[Attachments],
[CreationDate],
[RevisionDate],
[DeletedDate],
[Reprompt],
[Key]
)
VALUES
(
@Id,
CASE WHEN @OrganizationId IS NULL THEN @UserId ELSE NULL END,
@OrganizationId,
@Type,
@Data,
@Favorites,
@Folders,
@Attachments,
@CreationDate,
@RevisionDate,
@DeletedDate,
@Reprompt,
@Key
)
IF @OrganizationId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId
END
ELSE IF @UserId IS NOT NULL
BEGIN
EXEC [dbo].[User_BumpAccountRevisionDate] @UserId
END
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Cipher_CreateWithCollections]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX),
@Folders NVARCHAR(MAX),
@Attachments NVARCHAR(MAX),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL,
@CollectionIds AS [dbo].[GuidIdArray] READONLY
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[Cipher_Create] @Id, @UserId, @OrganizationId, @Type, @Data, @Favorites, @Folders,
@Attachments, @CreationDate, @RevisionDate, @DeletedDate, @Reprompt, @Key
DECLARE @UpdateCollectionsSuccess INT
EXEC @UpdateCollectionsSuccess = [dbo].[Cipher_UpdateCollections] @Id, @UserId, @OrganizationId, @CollectionIds
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Cipher_UpdateWithCollections]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX),
@Folders NVARCHAR(MAX),
@Attachments NVARCHAR(MAX),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL,
@CollectionIds AS [dbo].[GuidIdArray] READONLY
AS
BEGIN
SET NOCOUNT ON
BEGIN TRANSACTION Cipher_UpdateWithCollections
DECLARE @UpdateCollectionsSuccess INT
EXEC @UpdateCollectionsSuccess = [dbo].[Cipher_UpdateCollections] @Id, @UserId, @OrganizationId, @CollectionIds
IF @UpdateCollectionsSuccess < 0
BEGIN
COMMIT TRANSACTION Cipher_UpdateWithCollections
SELECT -1 -- -1 = Failure
RETURN
END
UPDATE
[dbo].[Cipher]
SET
[UserId] = NULL,
[OrganizationId] = @OrganizationId,
[Data] = @Data,
[Attachments] = @Attachments,
[RevisionDate] = @RevisionDate,
[DeletedDate] = @DeletedDate,
[Key] = @Key
-- No need to update CreationDate, Favorites, Folders, or Type since that data will not change
WHERE
[Id] = @Id
COMMIT TRANSACTION Cipher_UpdateWithCollections
IF @Attachments IS NOT NULL
BEGIN
EXEC [dbo].[Organization_UpdateStorage] @OrganizationId
EXEC [dbo].[User_UpdateStorage] @UserId
END
EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId
SELECT 0 -- 0 = Success
END
GO
CREATE OR ALTER PROCEDURE [dbo].[CipherDetails_CreateWithCollections]
@Id UNIQUEIDENTIFIER,
@UserId UNIQUEIDENTIFIER,
@OrganizationId UNIQUEIDENTIFIER,
@Type TINYINT,
@Data NVARCHAR(MAX),
@Favorites NVARCHAR(MAX), -- not used
@Folders NVARCHAR(MAX), -- not used
@Attachments NVARCHAR(MAX), -- not used
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@FolderId UNIQUEIDENTIFIER,
@Favorite BIT,
@Edit BIT, -- not used
@ViewPassword BIT, -- not used
@OrganizationUseTotp BIT, -- not used
@DeletedDate DATETIME2(7),
@Reprompt TINYINT,
@Key VARCHAR(MAX) = NULL,
@CollectionIds AS [dbo].[GuidIdArray] READONLY
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[CipherDetails_Create] @Id, @UserId, @OrganizationId, @Type, @Data, @Favorites, @Folders,
@Attachments, @CreationDate, @RevisionDate, @FolderId, @Favorite, @Edit, @ViewPassword,
@OrganizationUseTotp, @DeletedDate, @Reprompt, @Key
DECLARE @UpdateCollectionsSuccess INT
EXEC @UpdateCollectionsSuccess = [dbo].[Cipher_UpdateCollections] @Id, @UserId, @OrganizationId, @CollectionIds
END
GO