mirror of
https://github.com/bitwarden/server.git
synced 2024-11-27 13:05:23 +01:00
d9aa27d4cb
* Copy v2 sprocs and drop v2 suffix
534 lines
14 KiB
Transact-SQL
534 lines
14 KiB
Transact-SQL
-- Drop the v2 naming for sprocs that added the CollectionUser.Manage and CollectionGroup.Manage columns.
|
|
-- Step 1: copy existing sprocs and drop the v2 suffix. Current v2 sprocs will be left for EDD rollback support.
|
|
|
|
-- Collection_CreateWithGroupsAndUsers
|
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers]
|
|
@Id UNIQUEIDENTIFIER,
|
|
@OrganizationId UNIQUEIDENTIFIER,
|
|
@Name VARCHAR(MAX),
|
|
@ExternalId NVARCHAR(300),
|
|
@CreationDate DATETIME2(7),
|
|
@RevisionDate DATETIME2(7),
|
|
@Groups AS [dbo].[CollectionAccessSelectionType] READONLY,
|
|
@Users AS [dbo].[CollectionAccessSelectionType] READONLY
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
EXEC [dbo].[Collection_Create] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate
|
|
|
|
-- Groups
|
|
;WITH [AvailableGroupsCTE] AS(
|
|
SELECT
|
|
[Id]
|
|
FROM
|
|
[dbo].[Group]
|
|
WHERE
|
|
[OrganizationId] = @OrganizationId
|
|
)
|
|
INSERT INTO [dbo].[CollectionGroup]
|
|
(
|
|
[CollectionId],
|
|
[GroupId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
SELECT
|
|
@Id,
|
|
[Id],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
FROM
|
|
@Groups
|
|
WHERE
|
|
[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE])
|
|
|
|
-- Users
|
|
;WITH [AvailableUsersCTE] AS(
|
|
SELECT
|
|
[Id]
|
|
FROM
|
|
[dbo].[OrganizationUser]
|
|
WHERE
|
|
[OrganizationId] = @OrganizationId
|
|
)
|
|
INSERT INTO [dbo].[CollectionUser]
|
|
(
|
|
[CollectionId],
|
|
[OrganizationUserId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
SELECT
|
|
@Id,
|
|
[Id],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
FROM
|
|
@Users
|
|
WHERE
|
|
[Id] IN (SELECT [Id] FROM [AvailableUsersCTE])
|
|
|
|
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId
|
|
END
|
|
GO
|
|
|
|
-- Collection_UpdateWithGroupsAndUsers
|
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers]
|
|
@Id UNIQUEIDENTIFIER,
|
|
@OrganizationId UNIQUEIDENTIFIER,
|
|
@Name VARCHAR(MAX),
|
|
@ExternalId NVARCHAR(300),
|
|
@CreationDate DATETIME2(7),
|
|
@RevisionDate DATETIME2(7),
|
|
@Groups AS [dbo].[CollectionAccessSelectionType] READONLY,
|
|
@Users AS [dbo].[CollectionAccessSelectionType] READONLY
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate
|
|
|
|
-- Groups
|
|
;WITH [AvailableGroupsCTE] AS(
|
|
SELECT
|
|
Id
|
|
FROM
|
|
[dbo].[Group]
|
|
WHERE
|
|
OrganizationId = @OrganizationId
|
|
)
|
|
MERGE
|
|
[dbo].[CollectionGroup] AS [Target]
|
|
USING
|
|
@Groups AS [Source]
|
|
ON
|
|
[Target].[CollectionId] = @Id
|
|
AND [Target].[GroupId] = [Source].[Id]
|
|
WHEN NOT MATCHED BY TARGET
|
|
AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN
|
|
INSERT -- Add explicit column list
|
|
(
|
|
[CollectionId],
|
|
[GroupId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
VALUES
|
|
(
|
|
@Id,
|
|
[Source].[Id],
|
|
[Source].[ReadOnly],
|
|
[Source].[HidePasswords],
|
|
[Source].[Manage]
|
|
)
|
|
WHEN MATCHED AND (
|
|
[Target].[ReadOnly] != [Source].[ReadOnly]
|
|
OR [Target].[HidePasswords] != [Source].[HidePasswords]
|
|
OR [Target].[Manage] != [Source].[Manage]
|
|
) THEN
|
|
UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly],
|
|
[Target].[HidePasswords] = [Source].[HidePasswords],
|
|
[Target].[Manage] = [Source].[Manage]
|
|
WHEN NOT MATCHED BY SOURCE
|
|
AND [Target].[CollectionId] = @Id THEN
|
|
DELETE
|
|
;
|
|
|
|
-- Users
|
|
;WITH [AvailableGroupsCTE] AS(
|
|
SELECT
|
|
Id
|
|
FROM
|
|
[dbo].[OrganizationUser]
|
|
WHERE
|
|
OrganizationId = @OrganizationId
|
|
)
|
|
MERGE
|
|
[dbo].[CollectionUser] AS [Target]
|
|
USING
|
|
@Users AS [Source]
|
|
ON
|
|
[Target].[CollectionId] = @Id
|
|
AND [Target].[OrganizationUserId] = [Source].[Id]
|
|
WHEN NOT MATCHED BY TARGET
|
|
AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN
|
|
INSERT
|
|
(
|
|
[CollectionId],
|
|
[OrganizationUserId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
VALUES
|
|
(
|
|
@Id,
|
|
[Source].[Id],
|
|
[Source].[ReadOnly],
|
|
[Source].[HidePasswords],
|
|
[Source].[Manage]
|
|
)
|
|
WHEN MATCHED AND (
|
|
[Target].[ReadOnly] != [Source].[ReadOnly]
|
|
OR [Target].[HidePasswords] != [Source].[HidePasswords]
|
|
OR [Target].[Manage] != [Source].[Manage]
|
|
) THEN
|
|
UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly],
|
|
[Target].[HidePasswords] = [Source].[HidePasswords],
|
|
[Target].[Manage] = [Source].[Manage]
|
|
WHEN NOT MATCHED BY SOURCE
|
|
AND [Target].[CollectionId] = @Id THEN
|
|
DELETE
|
|
;
|
|
|
|
EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId
|
|
END
|
|
GO
|
|
|
|
-- CollectionUser_UpdateUsers
|
|
CREATE OR ALTER PROCEDURE [dbo].[CollectionUser_UpdateUsers]
|
|
@CollectionId UNIQUEIDENTIFIER,
|
|
@Users AS [dbo].[CollectionAccessSelectionType] READONLY
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
DECLARE @OrgId UNIQUEIDENTIFIER = (
|
|
SELECT TOP 1
|
|
[OrganizationId]
|
|
FROM
|
|
[dbo].[Collection]
|
|
WHERE
|
|
[Id] = @CollectionId
|
|
)
|
|
|
|
-- Update
|
|
UPDATE
|
|
[Target]
|
|
SET
|
|
[Target].[ReadOnly] = [Source].[ReadOnly],
|
|
[Target].[HidePasswords] = [Source].[HidePasswords],
|
|
[Target].[Manage] = [Source].[Manage]
|
|
FROM
|
|
[dbo].[CollectionUser] [Target]
|
|
INNER JOIN
|
|
@Users [Source] ON [Source].[Id] = [Target].[OrganizationUserId]
|
|
WHERE
|
|
[Target].[CollectionId] = @CollectionId
|
|
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
|
|
@CollectionId,
|
|
[Source].[Id],
|
|
[Source].[ReadOnly],
|
|
[Source].[HidePasswords],
|
|
[Source].[Manage]
|
|
FROM
|
|
@Users [Source]
|
|
INNER JOIN
|
|
[dbo].[OrganizationUser] OU ON [Source].[Id] = OU.[Id] AND OU.[OrganizationId] = @OrgId
|
|
WHERE
|
|
NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
[dbo].[CollectionUser]
|
|
WHERE
|
|
[CollectionId] = @CollectionId
|
|
AND [OrganizationUserId] = [Source].[Id]
|
|
)
|
|
|
|
-- Delete
|
|
DELETE
|
|
CU
|
|
FROM
|
|
[dbo].[CollectionUser] CU
|
|
WHERE
|
|
CU.[CollectionId] = @CollectionId
|
|
AND NOT EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
@Users
|
|
WHERE
|
|
[Id] = CU.[OrganizationUserId]
|
|
)
|
|
|
|
EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrgId
|
|
END
|
|
GO
|
|
|
|
-- Group_CreateWithCollections
|
|
CREATE OR ALTER PROCEDURE [dbo].[Group_CreateWithCollections]
|
|
@Id UNIQUEIDENTIFIER,
|
|
@OrganizationId UNIQUEIDENTIFIER,
|
|
@Name NVARCHAR(100),
|
|
@AccessAll BIT,
|
|
@ExternalId NVARCHAR(300),
|
|
@CreationDate DATETIME2(7),
|
|
@RevisionDate DATETIME2(7),
|
|
@Collections AS [dbo].[CollectionAccessSelectionType] READONLY
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
EXEC [dbo].[Group_Create] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate
|
|
|
|
;WITH [AvailableCollectionsCTE] AS(
|
|
SELECT
|
|
[Id]
|
|
FROM
|
|
[dbo].[Collection]
|
|
WHERE
|
|
[OrganizationId] = @OrganizationId
|
|
)
|
|
INSERT INTO [dbo].[CollectionGroup]
|
|
(
|
|
[CollectionId],
|
|
[GroupId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
SELECT
|
|
[Id],
|
|
@Id,
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
FROM
|
|
@Collections
|
|
WHERE
|
|
[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE])
|
|
|
|
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId
|
|
END
|
|
GO
|
|
|
|
-- Group_UpdateWithCollections
|
|
CREATE OR ALTER PROCEDURE [dbo].[Group_UpdateWithCollections]
|
|
@Id UNIQUEIDENTIFIER,
|
|
@OrganizationId UNIQUEIDENTIFIER,
|
|
@Name NVARCHAR(100),
|
|
@AccessAll BIT,
|
|
@ExternalId NVARCHAR(300),
|
|
@CreationDate DATETIME2(7),
|
|
@RevisionDate DATETIME2(7),
|
|
@Collections AS [dbo].[CollectionAccessSelectionType] READONLY
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
|
|
EXEC [dbo].[Group_Update] @Id, @OrganizationId, @Name, @AccessAll, @ExternalId, @CreationDate, @RevisionDate
|
|
|
|
;WITH [AvailableCollectionsCTE] AS(
|
|
SELECT
|
|
Id
|
|
FROM
|
|
[dbo].[Collection]
|
|
WHERE
|
|
OrganizationId = @OrganizationId
|
|
)
|
|
MERGE
|
|
[dbo].[CollectionGroup] AS [Target]
|
|
USING
|
|
@Collections AS [Source]
|
|
ON
|
|
[Target].[CollectionId] = [Source].[Id]
|
|
AND [Target].[GroupId] = @Id
|
|
WHEN NOT MATCHED BY TARGET
|
|
AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN
|
|
INSERT
|
|
(
|
|
[CollectionId],
|
|
[GroupId],
|
|
[ReadOnly],
|
|
[HidePasswords],
|
|
[Manage]
|
|
)
|
|
VALUES
|
|
(
|
|
[Source].[Id],
|
|
@Id,
|
|
[Source].[ReadOnly],
|
|
[Source].[HidePasswords],
|
|
[Source].[Manage]
|
|
)
|
|
WHEN MATCHED AND (
|
|
[Target].[ReadOnly] != [Source].[ReadOnly]
|
|
OR [Target].[HidePasswords] != [Source].[HidePasswords]
|
|
OR [Target].[Manage] != [Source].[Manage]
|
|
) THEN
|
|
UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly],
|
|
[Target].[HidePasswords] = [Source].[HidePasswords],
|
|
[Target].[Manage] = [Source].[Manage]
|
|
WHEN NOT MATCHED BY SOURCE
|
|
AND [Target].[GroupId] = @Id THEN
|
|
DELETE
|
|
;
|
|
|
|
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId
|
|
END
|
|
GO
|
|
|
|
|
|
-- OrganizationUser_CreateWithCollections
|
|
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,
|
|
@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
|
|
|
|
-- OrganizationUser_UpdateWithCollections
|
|
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,
|
|
@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
|