mirror of
https://github.com/bitwarden/server.git
synced 2024-12-02 13:53:23 +01:00
846 lines
22 KiB
MySQL
846 lines
22 KiB
MySQL
|
/*
|
||
|
* Add Manage permission to collections and update associated stored procedures
|
||
|
*/
|
||
|
|
||
|
-- To allow the migration to be re-run, drop any of the V2 procedures as they depend on a new type
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[Group_UpdateWithCollections_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[Group_UpdateWithCollections_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[Collection_UpdateWithGroupsAndUsers_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[OrganizationUser_UpdateWithCollections_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[Group_CreateWithCollections_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[Group_CreateWithCollections_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[OrganizationUser_CreateWithCollections_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[OrganizationUser_CreateWithCollections_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
IF OBJECT_ID('[dbo].[Collection_CreateWithGroupsAndUsers_V2]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers_V2]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Create a new CollectionAccessSelectionType with a new [Manage] column
|
||
|
IF TYPE_ID('[dbo].[CollectionAccessSelectionType]') IS NOT NULL
|
||
|
BEGIN
|
||
|
DROP TYPE [dbo].[CollectionAccessSelectionType]
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
CREATE TYPE [dbo].[CollectionAccessSelectionType] AS TABLE (
|
||
|
[Id] UNIQUEIDENTIFIER NOT NULL,
|
||
|
[ReadOnly] BIT NOT NULL,
|
||
|
[HidePasswords] BIT NOT NULL,
|
||
|
[Manage] BIT NOT NULL);
|
||
|
GO
|
||
|
|
||
|
-- Add Manage Column
|
||
|
IF COL_LENGTH('[dbo].[CollectionUser]', 'Manage') IS NULL
|
||
|
BEGIN
|
||
|
ALTER TABLE [dbo].[CollectionUser] ADD [Manage] BIT NOT NULL CONSTRAINT D_CollectionUser_Manage DEFAULT (0);
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Add Manage Column
|
||
|
IF COL_LENGTH('[dbo].[CollectionGroup]', 'Manage') IS NULL
|
||
|
BEGIN
|
||
|
ALTER TABLE [dbo].[CollectionGroup] ADD [Manage] BIT NOT NULL CONSTRAINT D_CollectionGroup_Manage DEFAULT (0);
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- BEGIN Update procedures that support backwards compatability in place
|
||
|
-- These procedures can be safely used by server in case of rollback and do not require V2 versions
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[CollectionUser_ReadByCollectionId]
|
||
|
@CollectionId UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
SELECT
|
||
|
[OrganizationUserId] [Id],
|
||
|
[ReadOnly],
|
||
|
[HidePasswords],
|
||
|
[Manage]
|
||
|
FROM
|
||
|
[dbo].[CollectionUser]
|
||
|
WHERE
|
||
|
[CollectionId] = @CollectionId
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[CollectionGroup_ReadByCollectionId]
|
||
|
@CollectionId UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
SELECT
|
||
|
[GroupId] [Id],
|
||
|
[ReadOnly],
|
||
|
[HidePasswords],
|
||
|
[Manage]
|
||
|
FROM
|
||
|
[dbo].[CollectionGroup]
|
||
|
WHERE
|
||
|
[CollectionId] = @CollectionId
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUserUserDetails_ReadWithCollectionsById]
|
||
|
@Id UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
EXEC [OrganizationUserUserDetails_ReadById] @Id
|
||
|
|
||
|
SELECT
|
||
|
CU.[CollectionId] Id,
|
||
|
CU.[ReadOnly],
|
||
|
CU.[HidePasswords],
|
||
|
CU.[Manage]
|
||
|
FROM
|
||
|
[dbo].[OrganizationUser] OU
|
||
|
INNER JOIN
|
||
|
[dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = [OU].[Id]
|
||
|
WHERE
|
||
|
[OrganizationUserId] = @Id
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly function that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER FUNCTION [dbo].[UserCollectionDetails](@UserId UNIQUEIDENTIFIER)
|
||
|
RETURNS TABLE
|
||
|
AS RETURN
|
||
|
SELECT
|
||
|
C.*,
|
||
|
CASE
|
||
|
WHEN
|
||
|
OU.[AccessAll] = 1
|
||
|
OR G.[AccessAll] = 1
|
||
|
OR COALESCE(CU.[ReadOnly], CG.[ReadOnly], 0) = 0
|
||
|
THEN 0
|
||
|
ELSE 1
|
||
|
END [ReadOnly],
|
||
|
CASE
|
||
|
WHEN
|
||
|
OU.[AccessAll] = 1
|
||
|
OR G.[AccessAll] = 1
|
||
|
OR COALESCE(CU.[HidePasswords], CG.[HidePasswords], 0) = 0
|
||
|
THEN 0
|
||
|
ELSE 1
|
||
|
END [HidePasswords],
|
||
|
CASE
|
||
|
WHEN
|
||
|
OU.[AccessAll] = 1
|
||
|
OR G.[AccessAll] = 1
|
||
|
OR COALESCE(CU.[Manage], CG.[Manage], 0) = 0
|
||
|
THEN 0
|
||
|
ELSE 1
|
||
|
END [Manage]
|
||
|
FROM
|
||
|
[dbo].[CollectionView] C
|
||
|
INNER JOIN
|
||
|
[dbo].[OrganizationUser] OU ON C.[OrganizationId] = OU.[OrganizationId]
|
||
|
INNER JOIN
|
||
|
[dbo].[Organization] O ON O.[Id] = C.[OrganizationId]
|
||
|
LEFT JOIN
|
||
|
[dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[CollectionId] = C.[Id] AND CU.[OrganizationUserId] = [OU].[Id]
|
||
|
LEFT JOIN
|
||
|
[dbo].[GroupUser] GU ON CU.[CollectionId] IS NULL AND OU.[AccessAll] = 0 AND GU.[OrganizationUserId] = OU.[Id]
|
||
|
LEFT JOIN
|
||
|
[dbo].[Group] G ON G.[Id] = GU.[GroupId]
|
||
|
LEFT JOIN
|
||
|
[dbo].[CollectionGroup] CG ON G.[AccessAll] = 0 AND CG.[CollectionId] = C.[Id] AND CG.[GroupId] = GU.[GroupId]
|
||
|
WHERE
|
||
|
OU.[UserId] = @UserId
|
||
|
AND OU.[Status] = 2 -- 2 = Confirmed
|
||
|
AND O.[Enabled] = 1
|
||
|
AND (
|
||
|
OU.[AccessAll] = 1
|
||
|
OR CU.[CollectionId] IS NOT NULL
|
||
|
OR G.[AccessAll] = 1
|
||
|
OR CG.[CollectionId] IS NOT NULL
|
||
|
)
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByIdUserId]
|
||
|
@Id UNIQUEIDENTIFIER,
|
||
|
@UserId UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
SELECT
|
||
|
Id,
|
||
|
OrganizationId,
|
||
|
[Name],
|
||
|
CreationDate,
|
||
|
RevisionDate,
|
||
|
ExternalId,
|
||
|
MIN([ReadOnly]) AS [ReadOnly],
|
||
|
MIN([HidePasswords]) AS [HidePasswords],
|
||
|
MIN([Manage]) AS [Manage]
|
||
|
FROM
|
||
|
[dbo].[UserCollectionDetails](@UserId)
|
||
|
WHERE
|
||
|
[Id] = @Id
|
||
|
GROUP BY
|
||
|
Id,
|
||
|
OrganizationId,
|
||
|
[Name],
|
||
|
CreationDate,
|
||
|
RevisionDate,
|
||
|
ExternalId
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadByUserId]
|
||
|
@UserId UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
SELECT
|
||
|
Id,
|
||
|
OrganizationId,
|
||
|
[Name],
|
||
|
CreationDate,
|
||
|
RevisionDate,
|
||
|
ExternalId,
|
||
|
MIN([ReadOnly]) AS [ReadOnly],
|
||
|
MIN([HidePasswords]) AS [HidePasswords],
|
||
|
MIN([Manage]) AS [Manage]
|
||
|
FROM
|
||
|
[dbo].[UserCollectionDetails](@UserId)
|
||
|
GROUP BY
|
||
|
Id,
|
||
|
OrganizationId,
|
||
|
[Name],
|
||
|
CreationDate,
|
||
|
RevisionDate,
|
||
|
ExternalId
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_ReadWithGroupsAndUsersByUserId]
|
||
|
@UserId UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
DECLARE @TempUserCollections TABLE(
|
||
|
Id UNIQUEIDENTIFIER,
|
||
|
OrganizationId UNIQUEIDENTIFIER,
|
||
|
Name VARCHAR(MAX),
|
||
|
CreationDate DATETIME2(7),
|
||
|
RevisionDate DATETIME2(7),
|
||
|
ExternalId NVARCHAR(300),
|
||
|
ReadOnly BIT,
|
||
|
HidePasswords BIT,
|
||
|
Manage BIT)
|
||
|
|
||
|
INSERT INTO @TempUserCollections EXEC [dbo].[Collection_ReadByUserId] @UserId
|
||
|
|
||
|
SELECT
|
||
|
*
|
||
|
FROM
|
||
|
@TempUserCollections C
|
||
|
|
||
|
SELECT
|
||
|
CG.*
|
||
|
FROM
|
||
|
[dbo].[CollectionGroup] CG
|
||
|
INNER JOIN
|
||
|
@TempUserCollections C ON C.[Id] = CG.[CollectionId]
|
||
|
|
||
|
SELECT
|
||
|
CU.*
|
||
|
FROM
|
||
|
[dbo].[CollectionUser] CU
|
||
|
INNER JOIN
|
||
|
@TempUserCollections C ON C.[Id] = CU.[CollectionId]
|
||
|
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- Readonly query that adds [Manage] column to result, safely ignored by rolled back server
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Group_ReadWithCollectionsById]
|
||
|
@Id UNIQUEIDENTIFIER
|
||
|
AS
|
||
|
BEGIN
|
||
|
SET NOCOUNT ON
|
||
|
|
||
|
EXEC [dbo].[Group_ReadById] @Id
|
||
|
|
||
|
SELECT
|
||
|
[CollectionId] [Id],
|
||
|
[ReadOnly],
|
||
|
[HidePasswords],
|
||
|
[Manage]
|
||
|
FROM
|
||
|
[dbo].[CollectionGroup]
|
||
|
WHERE
|
||
|
[GroupId] = @Id
|
||
|
END
|
||
|
GO
|
||
|
|
||
|
-- END Update procedures that support backwards compatability in place
|
||
|
|
||
|
-- BEGIN Create V2 of existing procedures to support new [Manage] column and new CollectionAccessSelectionType
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[CollectionUser_UpdateUsers_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Group_UpdateWithCollections_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_UpdateWithGroupsAndUsers_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Group_CreateWithCollections_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_CreateWithCollections_V2]
|
||
|
@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
|
||
|
|
||
|
CREATE OR ALTER PROCEDURE [dbo].[Collection_CreateWithGroupsAndUsers_V2]
|
||
|
@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
|