1
0
mirror of https://github.com/bitwarden/server.git synced 2024-12-26 17:37:36 +01:00
bitwarden-server/util/Migrator/DbScripts/2023-01-06_00_SecretsManager.sql
Oscar Hinton 1f0fc43278
[SM-394] Secrets Manager (#2164)
Long lived feature branch for Secrets Manager

Co-authored-by: Thomas Avery <43214426+Thomas-Avery@users.noreply.github.com>
Co-authored-by: cd-bitwarden <106776772+cd-bitwarden@users.noreply.github.com>
Co-authored-by: CarleyDiaz-Bitwarden <103955722+CarleyDiaz-Bitwarden@users.noreply.github.com>
Co-authored-by: Thomas Avery <tavery@bitwarden.com>
Co-authored-by: Colton Hurst <colton@coltonhurst.com>
2023-01-13 15:02:53 +01:00

808 lines
20 KiB
Transact-SQL

IF COL_LENGTH('[dbo].[Organization]', 'UseSecretsManager') IS NULL
BEGIN
ALTER TABLE
[dbo].[Organization]
ADD
[UseSecretsManager] BIT NOT NULL CONSTRAINT [DF_Organization_UseSecretsManager] DEFAULT (0)
END
GO
CREATE OR ALTER VIEW [dbo].[OrganizationUserOrganizationDetailsView]
AS
SELECT
OU.[UserId],
OU.[OrganizationId],
O.[Name],
O.[Enabled],
O.[PlanType],
O.[UsePolicies],
O.[UseSso],
O.[UseKeyConnector],
O.[UseScim],
O.[UseGroups],
O.[UseDirectory],
O.[UseEvents],
O.[UseTotp],
O.[Use2fa],
O.[UseApi],
O.[UseResetPassword],
O.[SelfHost],
O.[UsersGetPremium],
O.[UseCustomPermissions],
O.[UseSecretsManager],
O.[Seats],
O.[MaxCollections],
O.[MaxStorageGb],
O.[Identifier],
OU.[Key],
OU.[ResetPasswordKey],
O.[PublicKey],
O.[PrivateKey],
OU.[Status],
OU.[Type],
SU.[ExternalId] SsoExternalId,
OU.[Permissions],
PO.[ProviderId],
P.[Name] ProviderName,
SS.[Data] SsoConfig,
OS.[FriendlyName] FamilySponsorshipFriendlyName,
OS.[LastSyncDate] FamilySponsorshipLastSyncDate,
OS.[ToDelete] FamilySponsorshipToDelete,
OS.[ValidUntil] FamilySponsorshipValidUntil
FROM
[dbo].[OrganizationUser] OU
LEFT JOIN
[dbo].[Organization] O ON O.[Id] = OU.[OrganizationId]
LEFT JOIN
[dbo].[SsoUser] SU ON SU.[UserId] = OU.[UserId] AND SU.[OrganizationId] = OU.[OrganizationId]
LEFT JOIN
[dbo].[ProviderOrganization] PO ON PO.[OrganizationId] = O.[Id]
LEFT JOIN
[dbo].[Provider] P ON P.[Id] = PO.[ProviderId]
LEFT JOIN
[dbo].[SsoConfig] SS ON SS.[OrganizationId] = OU.[OrganizationId]
LEFT JOIN
[dbo].[OrganizationSponsorship] OS ON OS.[SponsoringOrganizationUserID] = OU.[Id]
GO
CREATE OR ALTER PROCEDURE [dbo].[Organization_Create]
@Id UNIQUEIDENTIFIER OUTPUT,
@Identifier NVARCHAR(50),
@Name NVARCHAR(50),
@BusinessName NVARCHAR(50),
@BusinessAddress1 NVARCHAR(50),
@BusinessAddress2 NVARCHAR(50),
@BusinessAddress3 NVARCHAR(50),
@BusinessCountry VARCHAR(2),
@BusinessTaxNumber NVARCHAR(30),
@BillingEmail NVARCHAR(256),
@Plan NVARCHAR(50),
@PlanType TINYINT,
@Seats INT,
@MaxCollections SMALLINT,
@UsePolicies BIT,
@UseSso BIT,
@UseGroups BIT,
@UseDirectory BIT,
@UseEvents BIT,
@UseTotp BIT,
@Use2fa BIT,
@UseApi BIT,
@UseResetPassword BIT,
@SelfHost BIT,
@UsersGetPremium BIT,
@Storage BIGINT,
@MaxStorageGb SMALLINT,
@Gateway TINYINT,
@GatewayCustomerId VARCHAR(50),
@GatewaySubscriptionId VARCHAR(50),
@ReferenceData VARCHAR(MAX),
@Enabled BIT,
@LicenseKey VARCHAR(100),
@PublicKey VARCHAR(MAX),
@PrivateKey VARCHAR(MAX),
@TwoFactorProviders NVARCHAR(MAX),
@ExpirationDate DATETIME2(7),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@OwnersNotifiedOfAutoscaling DATETIME2(7),
@MaxAutoscaleSeats INT,
@UseKeyConnector BIT = 0,
@UseScim BIT = 0,
@UseCustomPermissions BIT = 0,
@UseSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
INSERT INTO [dbo].[Organization]
(
[Id],
[Identifier],
[Name],
[BusinessName],
[BusinessAddress1],
[BusinessAddress2],
[BusinessAddress3],
[BusinessCountry],
[BusinessTaxNumber],
[BillingEmail],
[Plan],
[PlanType],
[Seats],
[MaxCollections],
[UsePolicies],
[UseSso],
[UseGroups],
[UseDirectory],
[UseEvents],
[UseTotp],
[Use2fa],
[UseApi],
[UseResetPassword],
[SelfHost],
[UsersGetPremium],
[Storage],
[MaxStorageGb],
[Gateway],
[GatewayCustomerId],
[GatewaySubscriptionId],
[ReferenceData],
[Enabled],
[LicenseKey],
[PublicKey],
[PrivateKey],
[TwoFactorProviders],
[ExpirationDate],
[CreationDate],
[RevisionDate],
[OwnersNotifiedOfAutoscaling],
[MaxAutoscaleSeats],
[UseKeyConnector],
[UseScim],
[UseCustomPermissions],
[UseSecretsManager]
)
VALUES
(
@Id,
@Identifier,
@Name,
@BusinessName,
@BusinessAddress1,
@BusinessAddress2,
@BusinessAddress3,
@BusinessCountry,
@BusinessTaxNumber,
@BillingEmail,
@Plan,
@PlanType,
@Seats,
@MaxCollections,
@UsePolicies,
@UseSso,
@UseGroups,
@UseDirectory,
@UseEvents,
@UseTotp,
@Use2fa,
@UseApi,
@UseResetPassword,
@SelfHost,
@UsersGetPremium,
@Storage,
@MaxStorageGb,
@Gateway,
@GatewayCustomerId,
@GatewaySubscriptionId,
@ReferenceData,
@Enabled,
@LicenseKey,
@PublicKey,
@PrivateKey,
@TwoFactorProviders,
@ExpirationDate,
@CreationDate,
@RevisionDate,
@OwnersNotifiedOfAutoscaling,
@MaxAutoscaleSeats,
@UseKeyConnector,
@UseScim,
@UseCustomPermissions,
@UseSecretsManager
)
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Organization_Update]
@Id UNIQUEIDENTIFIER,
@Identifier NVARCHAR(50),
@Name NVARCHAR(50),
@BusinessName NVARCHAR(50),
@BusinessAddress1 NVARCHAR(50),
@BusinessAddress2 NVARCHAR(50),
@BusinessAddress3 NVARCHAR(50),
@BusinessCountry VARCHAR(2),
@BusinessTaxNumber NVARCHAR(30),
@BillingEmail NVARCHAR(256),
@Plan NVARCHAR(50),
@PlanType TINYINT,
@Seats INT,
@MaxCollections SMALLINT,
@UsePolicies BIT,
@UseSso BIT,
@UseGroups BIT,
@UseDirectory BIT,
@UseEvents BIT,
@UseTotp BIT,
@Use2fa BIT,
@UseApi BIT,
@UseResetPassword BIT,
@SelfHost BIT,
@UsersGetPremium BIT,
@Storage BIGINT,
@MaxStorageGb SMALLINT,
@Gateway TINYINT,
@GatewayCustomerId VARCHAR(50),
@GatewaySubscriptionId VARCHAR(50),
@ReferenceData VARCHAR(MAX),
@Enabled BIT,
@LicenseKey VARCHAR(100),
@PublicKey VARCHAR(MAX),
@PrivateKey VARCHAR(MAX),
@TwoFactorProviders NVARCHAR(MAX),
@ExpirationDate DATETIME2(7),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7),
@OwnersNotifiedOfAutoscaling DATETIME2(7),
@MaxAutoscaleSeats INT,
@UseKeyConnector BIT = 0,
@UseScim BIT = 0,
@UseCustomPermissions BIT = 0,
@UseSecretsManager BIT = 0
AS
BEGIN
SET NOCOUNT ON
UPDATE
[dbo].[Organization]
SET
[Identifier] = @Identifier,
[Name] = @Name,
[BusinessName] = @BusinessName,
[BusinessAddress1] = @BusinessAddress1,
[BusinessAddress2] = @BusinessAddress2,
[BusinessAddress3] = @BusinessAddress3,
[BusinessCountry] = @BusinessCountry,
[BusinessTaxNumber] = @BusinessTaxNumber,
[BillingEmail] = @BillingEmail,
[Plan] = @Plan,
[PlanType] = @PlanType,
[Seats] = @Seats,
[MaxCollections] = @MaxCollections,
[UsePolicies] = @UsePolicies,
[UseSso] = @UseSso,
[UseGroups] = @UseGroups,
[UseDirectory] = @UseDirectory,
[UseEvents] = @UseEvents,
[UseTotp] = @UseTotp,
[Use2fa] = @Use2fa,
[UseApi] = @UseApi,
[UseResetPassword] = @UseResetPassword,
[SelfHost] = @SelfHost,
[UsersGetPremium] = @UsersGetPremium,
[Storage] = @Storage,
[MaxStorageGb] = @MaxStorageGb,
[Gateway] = @Gateway,
[GatewayCustomerId] = @GatewayCustomerId,
[GatewaySubscriptionId] = @GatewaySubscriptionId,
[ReferenceData] = @ReferenceData,
[Enabled] = @Enabled,
[LicenseKey] = @LicenseKey,
[PublicKey] = @PublicKey,
[PrivateKey] = @PrivateKey,
[TwoFactorProviders] = @TwoFactorProviders,
[ExpirationDate] = @ExpirationDate,
[CreationDate] = @CreationDate,
[RevisionDate] = @RevisionDate,
[OwnersNotifiedOfAutoscaling] = @OwnersNotifiedOfAutoscaling,
[MaxAutoscaleSeats] = @MaxAutoscaleSeats,
[UseKeyConnector] = @UseKeyConnector,
[UseScim] = @UseScim,
[UseCustomPermissions] = @UseCustomPermissions,
[UseSecretsManager] = @UseSecretsManager
WHERE
[Id] = @Id
END
GO
IF OBJECT_ID('[dbo].[Secret]') IS NULL
BEGIN
CREATE TABLE [dbo].[Secret]
(
[Id] UNIQUEIDENTIFIER NOT NULL,
[OrganizationId] UNIQUEIDENTIFIER NOT NULL,
[Key] NVARCHAR(MAX) NULL,
[Value] NVARCHAR(MAX) NULL,
[Note] NVARCHAR(MAX) NULL,
[CreationDate] DATETIME2(7) NOT NULL,
[RevisionDate] DATETIME2(7) NOT NULL,
[DeletedDate] DATETIME2(7) NULL,
CONSTRAINT [PK_Secret] PRIMARY KEY CLUSTERED ([Id] ASC),
CONSTRAINT [FK_Secret_OrganizationId] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization]([Id])
);
CREATE NONCLUSTERED INDEX [IX_Secret_OrganizationId] ON [dbo].[Secret] ([OrganizationId] ASC);
CREATE NONCLUSTERED INDEX [IX_Secret_DeletedDate] ON [dbo].[Secret] ([DeletedDate] ASC);
END
GO
IF OBJECT_ID('[dbo].[Project]') IS NULL
BEGIN
CREATE TABLE [dbo].[Project] (
[Id] UNIQUEIDENTIFIER NOT NULL,
[OrganizationId] UNIQUEIDENTIFIER NOT NULL,
[Name] NVARCHAR(MAX) NULL,
[CreationDate] DATETIME2 (7),
[RevisionDate] DATETIME2 (7),
[DeletedDate] DATETIME2 (7) NULL,
CONSTRAINT [PK_Project] PRIMARY KEY CLUSTERED ([Id] ASC),
CONSTRAINT [FK_Project_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id])
);
CREATE NONCLUSTERED INDEX [IX_Project_OrganizationId] ON [dbo].[Project] ([OrganizationId] ASC);
CREATE NONCLUSTERED INDEX [IX_Project_DeletedDate] ON [dbo].[Project] ([DeletedDate] ASC);
END
GO
IF OBJECT_ID('[dbo].[ProjectSecret]') IS NULL
BEGIN
CREATE TABLE [dbo].[ProjectSecret] (
[ProjectsId] uniqueidentifier NOT NULL,
[SecretsId] uniqueidentifier NOT NULL,
CONSTRAINT [PK_ProjectSecret] PRIMARY KEY ([ProjectsId], [SecretsId]),
CONSTRAINT [FK_ProjectSecret_Project_ProjectsId] FOREIGN KEY ([ProjectsId]) REFERENCES [Project] ([Id]) ON DELETE CASCADE,
CONSTRAINT [FK_ProjectSecret_Secret_SecretsId] FOREIGN KEY ([SecretsId]) REFERENCES [Secret] ([Id]) ON DELETE CASCADE
);
CREATE NONCLUSTERED INDEX [IX_ProjectSecret_SecretsId] ON [ProjectSecret] ([SecretsId]);
END
GO
IF OBJECT_ID('[dbo].[ServiceAccount]') IS NULL
BEGIN
CREATE TABLE [dbo].[ServiceAccount]
(
[Id] UNIQUEIDENTIFIER NOT NULL,
[OrganizationId] UNIQUEIDENTIFIER NOT NULL,
[Name] NVARCHAR(MAX) NULL,
[CreationDate] DATETIME2(7) NOT NULL,
[RevisionDate] DATETIME2(7) NOT NULL,
CONSTRAINT [PK_ServiceAccount] PRIMARY KEY CLUSTERED ([Id] ASC),
CONSTRAINT [FK_ServiceAccount_OrganizationId] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization]([Id])
);
CREATE NONCLUSTERED INDEX [IX_ServiceAccount_OrganizationId] ON [dbo].[ServiceAccount] ([OrganizationId] ASC);
END
GO
IF OBJECT_ID('[dbo].[ApiKey]') IS NULL
BEGIN
CREATE TABLE [dbo].[ApiKey] (
[Id] UNIQUEIDENTIFIER,
[ServiceAccountId] UNIQUEIDENTIFIER NULL,
[Name] VARCHAR(200) NOT NULL,
[ClientSecret] VARCHAR(30) NOT NULL,
[Scope] NVARCHAR (4000) NOT NULL,
[EncryptedPayload] NVARCHAR (4000) NOT NULL,
[Key] VARCHAR (MAX) NOT NULL,
[ExpireAt] DATETIME2(7) NULL,
[CreationDate] DATETIME2(7) NOT NULL,
[RevisionDate] DATETIME2(7) NOT NULL,
CONSTRAINT [PK_ApiKey] PRIMARY KEY CLUSTERED ([Id] ASC),
CONSTRAINT [FK_ApiKey_ServiceAccountId] FOREIGN KEY ([ServiceAccountId]) REFERENCES [dbo].[ServiceAccount] ([Id])
);
CREATE NONCLUSTERED INDEX [IX_ApiKey_ServiceAccountId]
ON [dbo].[ApiKey]([ServiceAccountId] ASC);
END
GO
CREATE OR ALTER VIEW [dbo].[ApiKeyDetailsView]
AS
SELECT
AK.*,
SA.[OrganizationId] ServiceAccountOrganizationId
FROM
[dbo].[ApiKey] AS AK
LEFT JOIN
[dbo].[ServiceAccount] SA ON SA.[Id] = AK.[ServiceAccountId]
GO
CREATE OR ALTER VIEW [dbo].[ApiKeyView]
AS
SELECT
*
FROM
[dbo].[ApiKey]
GO
CREATE OR ALTER PROCEDURE [dbo].[ApiKey_Create]
@Id UNIQUEIDENTIFIER OUTPUT,
@ServiceAccountId UNIQUEIDENTIFIER,
@Name VARCHAR(200),
@ClientSecret VARCHAR(30),
@Scope NVARCHAR(4000),
@EncryptedPayload NVARCHAR(4000),
@Key VARCHAR(MAX),
@ExpireAt DATETIME2(7),
@CreationDate DATETIME2(7),
@RevisionDate DATETIME2(7)
AS
BEGIN
SET NOCOUNT ON
INSERT INTO [dbo].[ApiKey]
(
[Id],
[ServiceAccountId],
[Name],
[ClientSecret],
[Scope],
[EncryptedPayload],
[Key],
[ExpireAt],
[CreationDate],
[RevisionDate]
)
VALUES
(
@Id,
@ServiceAccountId,
@Name,
@ClientSecret,
@Scope,
@EncryptedPayload,
@Key,
@ExpireAt,
@CreationDate,
@RevisionDate
)
END
GO
CREATE OR ALTER PROCEDURE [dbo].[ApiKey_ReadByServiceAccountId]
@ServiceAccountId UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON
SELECT
*
FROM
[dbo].[ApiKeyView]
WHERE
[ServiceAccountId] = @ServiceAccountId
END
GO
CREATE OR ALTER PROCEDURE [dbo].[ApiKeyDetails_ReadById]
@Id UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON
SELECT
*
FROM
[dbo].[ApiKeyDetailsView]
WHERE
[Id] = @Id
END
GO
IF OBJECT_ID('[dbo].[AccessPolicy]') IS NULL
BEGIN
CREATE TABLE [AccessPolicy] (
[Id] UNIQUEIDENTIFIER NOT NULL,
[Discriminator] NVARCHAR(50) NOT NULL,
[OrganizationUserId] UNIQUEIDENTIFIER NULL,
[GroupId] UNIQUEIDENTIFIER NULL,
[ServiceAccountId] UNIQUEIDENTIFIER NULL,
[GrantedProjectId] UNIQUEIDENTIFIER NULL,
[GrantedServiceAccountId] UNIQUEIDENTIFIER NULL,
[Read] BIT NOT NULL,
[Write] BIT NOT NULL,
[CreationDate] DATETIME2 NOT NULL,
[RevisionDate] DATETIME2 NOT NULL,
CONSTRAINT [PK_AccessPolicy] PRIMARY KEY CLUSTERED ([Id]),
CONSTRAINT [FK_AccessPolicy_Group_GroupId] FOREIGN KEY ([GroupId]) REFERENCES [Group] ([Id]) ON DELETE CASCADE,
CONSTRAINT [FK_AccessPolicy_OrganizationUser_OrganizationUserId] FOREIGN KEY ([OrganizationUserId]) REFERENCES [OrganizationUser] ([Id]),
CONSTRAINT [FK_AccessPolicy_Project_GrantedProjectId] FOREIGN KEY ([GrantedProjectId]) REFERENCES [Project] ([Id]) ON DELETE CASCADE,
CONSTRAINT [FK_AccessPolicy_ServiceAccount_GrantedServiceAccountId] FOREIGN KEY ([GrantedServiceAccountId]) REFERENCES [ServiceAccount] ([Id]),
CONSTRAINT [FK_AccessPolicy_ServiceAccount_ServiceAccountId] FOREIGN KEY ([ServiceAccountId]) REFERENCES [ServiceAccount] ([Id])
);
CREATE NONCLUSTERED INDEX [IX_AccessPolicy_GroupId] ON [AccessPolicy] ([GroupId]);
CREATE NONCLUSTERED INDEX [IX_AccessPolicy_OrganizationUserId] ON [AccessPolicy] ([OrganizationUserId]);
CREATE NONCLUSTERED INDEX [IX_AccessPolicy_GrantedProjectId] ON [AccessPolicy] ([GrantedProjectId]);
CREATE NONCLUSTERED INDEX [IX_AccessPolicy_ServiceAccountId] ON [AccessPolicy] ([ServiceAccountId]);
CREATE NONCLUSTERED INDEX [IX_AccessPolicy_GrantedServiceAccountId] ON [AccessPolicy] ([GrantedServiceAccountId]);
END
GO
CREATE OR ALTER PROCEDURE [dbo].[User_DeleteById]
@Id UNIQUEIDENTIFIER
WITH RECOMPILE
AS
BEGIN
SET NOCOUNT ON
DECLARE @BatchSize INT = 100
-- Delete ciphers
WHILE @BatchSize > 0
BEGIN
BEGIN TRANSACTION User_DeleteById_Ciphers
DELETE TOP(@BatchSize)
FROM
[dbo].[Cipher]
WHERE
[UserId] = @Id
SET @BatchSize = @@ROWCOUNT
COMMIT TRANSACTION User_DeleteById_Ciphers
END
BEGIN TRANSACTION User_DeleteById
-- Delete folders
DELETE
FROM
[dbo].[Folder]
WHERE
[UserId] = @Id
-- Delete devices
DELETE
FROM
[dbo].[Device]
WHERE
[UserId] = @Id
-- Delete collection users
DELETE
CU
FROM
[dbo].[CollectionUser] CU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = CU.[OrganizationUserId]
WHERE
OU.[UserId] = @Id
-- Delete group users
DELETE
GU
FROM
[dbo].[GroupUser] GU
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = GU.[OrganizationUserId]
WHERE
OU.[UserId] = @Id
-- Delete AccessPolicy
DELETE
AP
FROM
[dbo].[AccessPolicy] AP
INNER JOIN
[dbo].[OrganizationUser] OU ON OU.[Id] = AP.[OrganizationUserId]
WHERE
[UserId] = @Id
-- Delete organization users
DELETE
FROM
[dbo].[OrganizationUser]
WHERE
[UserId] = @Id
-- Delete provider users
DELETE
FROM
[dbo].[ProviderUser]
WHERE
[UserId] = @Id
-- Delete SSO Users
DELETE
FROM
[dbo].[SsoUser]
WHERE
[UserId] = @Id
-- Delete Emergency Accesses
DELETE
FROM
[dbo].[EmergencyAccess]
WHERE
[GrantorId] = @Id
OR
[GranteeId] = @Id
-- Delete Sends
DELETE
FROM
[dbo].[Send]
WHERE
[UserId] = @Id
-- Finally, delete the user
DELETE
FROM
[dbo].[User]
WHERE
[Id] = @Id
COMMIT TRANSACTION User_DeleteById
END
GO
CREATE OR ALTER PROCEDURE [dbo].[Organization_DeleteById]
@Id UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @Id
DECLARE @BatchSize INT = 100
WHILE @BatchSize > 0
BEGIN
BEGIN TRANSACTION Organization_DeleteById_Ciphers
DELETE TOP(@BatchSize)
FROM
[dbo].[Cipher]
WHERE
[UserId] IS NULL
AND [OrganizationId] = @Id
SET @BatchSize = @@ROWCOUNT
COMMIT TRANSACTION Organization_DeleteById_Ciphers
END
BEGIN TRANSACTION Organization_DeleteById
DELETE
FROM
[dbo].[SsoUser]
WHERE
[OrganizationId] = @Id
DELETE
FROM
[dbo].[SsoConfig]
WHERE
[OrganizationId] = @Id
DELETE CU
FROM
[dbo].[CollectionUser] CU
INNER JOIN
[dbo].[OrganizationUser] OU ON [CU].[OrganizationUserId] = [OU].[Id]
WHERE
[OU].[OrganizationId] = @Id
DELETE
FROM
[dbo].[OrganizationUser]
WHERE
[OrganizationId] = @Id
DELETE
FROM
[dbo].[ProviderOrganization]
WHERE
[OrganizationId] = @Id
EXEC [dbo].[OrganizationApiKey_OrganizationDeleted] @Id
EXEC [dbo].[OrganizationConnection_OrganizationDeleted] @Id
EXEC [dbo].[OrganizationSponsorship_OrganizationDeleted] @Id
DELETE
FROM
[dbo].[Project]
WHERE
[OrganizationId] = @Id
DELETE
FROM
[dbo].[Secret]
WHERE
[OrganizationId] = @Id
DELETE AK
FROM
[dbo].[ApiKey] AK
INNER JOIN
[dbo].[ServiceAccount] SA ON [AK].[ServiceAccountId] = [SA].[Id]
WHERE
[SA].[OrganizationId] = @Id
DELETE
FROM
[dbo].[ServiceAccount]
WHERE
[OrganizationId] = @Id
DELETE
FROM
[dbo].[Organization]
WHERE
[Id] = @Id
COMMIT TRANSACTION Organization_DeleteById
END
GO
CREATE OR ALTER PROCEDURE [dbo].[OrganizationUser_DeleteById]
@Id UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON
EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Id
DECLARE @OrganizationId UNIQUEIDENTIFIER
DECLARE @UserId UNIQUEIDENTIFIER
SELECT
@OrganizationId = [OrganizationId],
@UserId = [UserId]
FROM
[dbo].[OrganizationUser]
WHERE
[Id] = @Id
IF @OrganizationId IS NOT NULL AND @UserId IS NOT NULL
BEGIN
EXEC [dbo].[SsoUser_Delete] @UserId, @OrganizationId
END
DELETE
FROM
[dbo].[CollectionUser]
WHERE
[OrganizationUserId] = @Id
DELETE
FROM
[dbo].[GroupUser]
WHERE
[OrganizationUserId] = @Id
DELETE
FROM
[dbo].[AccessPolicy]
WHERE
[OrganizationUserId] = @Id
EXEC [dbo].[OrganizationSponsorship_OrganizationUserDeleted] @Id
DELETE
FROM
[dbo].[OrganizationUser]
WHERE
[Id] = @Id
END
GO