diff --git a/bitwarden-server.sln b/bitwarden-server.sln index 67197cde3..30fc71bb1 100644 --- a/bitwarden-server.sln +++ b/bitwarden-server.sln @@ -47,6 +47,8 @@ Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Core.Test", "test\Core.Test EndProject Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "EventsProcessor", "src\EventsProcessor\EventsProcessor.csproj", "{79BB453F-D0D8-4DDF-9809-A405C56692BD}" EndProject +Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "Migrator", "src\Migrator\Migrator.csproj", "{54DED792-A022-417E-9804-21FCC9C7C610}" +EndProject Global GlobalSection(SolutionConfigurationPlatforms) = preSolution Debug|Any CPU = Debug|Any CPU @@ -107,6 +109,10 @@ Global {79BB453F-D0D8-4DDF-9809-A405C56692BD}.Debug|Any CPU.Build.0 = Debug|Any CPU {79BB453F-D0D8-4DDF-9809-A405C56692BD}.Release|Any CPU.ActiveCfg = Release|Any CPU {79BB453F-D0D8-4DDF-9809-A405C56692BD}.Release|Any CPU.Build.0 = Release|Any CPU + {54DED792-A022-417E-9804-21FCC9C7C610}.Debug|Any CPU.ActiveCfg = Debug|Any CPU + {54DED792-A022-417E-9804-21FCC9C7C610}.Debug|Any CPU.Build.0 = Debug|Any CPU + {54DED792-A022-417E-9804-21FCC9C7C610}.Release|Any CPU.ActiveCfg = Release|Any CPU + {54DED792-A022-417E-9804-21FCC9C7C610}.Release|Any CPU.Build.0 = Release|Any CPU EndGlobalSection GlobalSection(SolutionProperties) = preSolution HideSolutionNode = FALSE @@ -125,6 +131,7 @@ Global {28635027-20E5-42FA-B218-B6C878DE5350} = {DD5BD056-4AAE-43EF-BBD2-0B569B8DA84D} {8EF31E6C-400A-4174-8BE3-502B08FB10B5} = {DD5BD056-4AAE-43EF-BBD2-0B569B8DA84F} {79BB453F-D0D8-4DDF-9809-A405C56692BD} = {DD5BD056-4AAE-43EF-BBD2-0B569B8DA84D} + {54DED792-A022-417E-9804-21FCC9C7C610} = {DD5BD056-4AAE-43EF-BBD2-0B569B8DA84D} EndGlobalSection GlobalSection(ExtensibilityGlobals) = postSolution SolutionGuid = {E01CBF68-2E20-425F-9EDB-E0A6510CA92F} diff --git a/src/Migrator/DbMigrator.cs b/src/Migrator/DbMigrator.cs new file mode 100644 index 000000000..b1865ba1c --- /dev/null +++ b/src/Migrator/DbMigrator.cs @@ -0,0 +1,69 @@ +using System; +using System.Data.SqlClient; +using System.Reflection; +using DbUp; + +namespace Bit.Migrator +{ + public static class DbMigrator + { + private static void MigrateMsSqlDatabase(string connectionString, int attempt = 1) + { + var masterConnectionString = new SqlConnectionStringBuilder(connectionString) + { + InitialCatalog = "master" + }.ConnectionString; + + try + { + using(var connection = new SqlConnection(masterConnectionString)) + { + var command = new SqlCommand( + "IF ((SELECT COUNT(1) FROM sys.databases WHERE [name] = 'vault') = 0) " + + "CREATE DATABASE [vault];", connection); + command.Connection.Open(); + command.ExecuteNonQuery(); + command.CommandText = "IF ((SELECT DATABASEPROPERTYEX([name], 'IsAutoClose') " + + "FROM sys.databases WHERE [name] = 'vault') = 1) " + + "ALTER DATABASE [vault] SET AUTO_CLOSE OFF;"; + command.ExecuteNonQuery(); + } + + var builder = DeployChanges.To + .SqlDatabase(connectionString) + .JournalToSqlTable("dbo", "Migration") + .WithScriptsAndCodeEmbeddedInAssembly(Assembly.GetExecutingAssembly(), + s => s.Contains($".DbScripts.") && !s.Contains(".Archive.")) + .WithTransaction() + .WithExecutionTimeout(new TimeSpan(0, 5, 0)) + .LogToConsole(); + + var upgrader = builder.Build(); + var result = upgrader.PerformUpgrade(); + if(result.Successful) + { + Console.WriteLine("Migration successful."); + } + else + { + Console.WriteLine("Migration failed."); + } + } + catch(SqlException e) + { + if(e.Message.Contains("Server is in script upgrade mode") && attempt < 10) + { + var nextAttempt = attempt + 1; + Console.WriteLine("Database is in script upgrade mode. " + + "Trying again (attempt #{0})...", nextAttempt); + System.Threading.Thread.Sleep(20000); + MigrateMsSqlDatabase(connectionString, nextAttempt); + return; + } + + throw e; + } + } + + } +} diff --git a/src/Migrator/DbScripts/2017-08-19_00_InitialSetup.sql b/src/Migrator/DbScripts/2017-08-19_00_InitialSetup.sql new file mode 100644 index 000000000..4cbad9129 --- /dev/null +++ b/src/Migrator/DbScripts/2017-08-19_00_InitialSetup.sql @@ -0,0 +1,4463 @@ +SET ANSI_NULLS, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL, QUOTED_IDENTIFIER ON; + +SET NUMERIC_ROUNDABORT OFF; + + +GO +PRINT N'Creating [dbo].[GuidIdArray]...'; + + +GO +CREATE TYPE [dbo].[GuidIdArray] AS TABLE ( + [Id] UNIQUEIDENTIFIER NOT NULL); + + +GO +PRINT N'Creating [dbo].[SelectionReadOnlyArray]...'; + + +GO +CREATE TYPE [dbo].[SelectionReadOnlyArray] AS TABLE ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [ReadOnly] BIT NOT NULL); + + +GO +PRINT N'Creating [dbo].[Cipher]...'; + + +GO +CREATE TABLE [dbo].[Cipher] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NULL, + [OrganizationId] UNIQUEIDENTIFIER NULL, + [Type] TINYINT NOT NULL, + [Data] NVARCHAR (MAX) NOT NULL, + [Favorites] NVARCHAR (MAX) NULL, + [Folders] NVARCHAR (MAX) NULL, + [Attachments] NVARCHAR (MAX) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Cipher] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[Cipher].[IX_Cipher_OrganizationId_Type]...'; + + +GO +CREATE NONCLUSTERED INDEX [IX_Cipher_OrganizationId_Type] + ON [dbo].[Cipher]([OrganizationId] ASC, [Type] ASC) WHERE ([OrganizationId] IS NOT NULL); + + +GO +PRINT N'Creating [dbo].[Cipher].[IX_Cipher_UserId_Type]...'; + + +GO +CREATE NONCLUSTERED INDEX [IX_Cipher_UserId_Type] + ON [dbo].[Cipher]([UserId] ASC, [Type] ASC); + + +GO +PRINT N'Creating [dbo].[Collection]...'; + + +GO +CREATE TABLE [dbo].[Collection] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [OrganizationId] UNIQUEIDENTIFIER NOT NULL, + [Name] VARCHAR (MAX) NOT NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Collection] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[CollectionCipher]...'; + + +GO +CREATE TABLE [dbo].[CollectionCipher] ( + [CollectionId] UNIQUEIDENTIFIER NOT NULL, + [CipherId] UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT [PK_CollectionCipher] PRIMARY KEY CLUSTERED ([CollectionId] ASC, [CipherId] ASC) +); + + +GO +PRINT N'Creating [dbo].[CollectionCipher].[IX_CollectionCipher_CipherId]...'; + + +GO +CREATE NONCLUSTERED INDEX [IX_CollectionCipher_CipherId] + ON [dbo].[CollectionCipher]([CipherId] ASC); + + +GO +PRINT N'Creating [dbo].[CollectionGroup]...'; + + +GO +CREATE TABLE [dbo].[CollectionGroup] ( + [CollectionId] UNIQUEIDENTIFIER NOT NULL, + [GroupId] UNIQUEIDENTIFIER NOT NULL, + [ReadOnly] BIT NOT NULL, + CONSTRAINT [PK_CollectionGroup] PRIMARY KEY CLUSTERED ([CollectionId] ASC, [GroupId] ASC) +); + + +GO +PRINT N'Creating [dbo].[CollectionUser]...'; + + +GO +CREATE TABLE [dbo].[CollectionUser] ( + [CollectionId] UNIQUEIDENTIFIER NOT NULL, + [OrganizationUserId] UNIQUEIDENTIFIER NOT NULL, + [ReadOnly] BIT NOT NULL, + CONSTRAINT [PK_CollectionUser] PRIMARY KEY CLUSTERED ([CollectionId] ASC, [OrganizationUserId] ASC) +); + + +GO +PRINT N'Creating [dbo].[Device]...'; + + +GO +CREATE TABLE [dbo].[Device] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NOT NULL, + [Name] NVARCHAR (50) NOT NULL, + [Type] SMALLINT NOT NULL, + [Identifier] NVARCHAR (50) NOT NULL, + [PushToken] NVARCHAR (255) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Device] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[Device].[UX_Device_UserId_Identifier]...'; + + +GO +CREATE UNIQUE NONCLUSTERED INDEX [UX_Device_UserId_Identifier] + ON [dbo].[Device]([UserId] ASC, [Identifier] ASC); + + +GO +PRINT N'Creating [dbo].[Folder]...'; + + +GO +CREATE TABLE [dbo].[Folder] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NOT NULL, + [Name] VARCHAR (MAX) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Folder] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[Grant]...'; + + +GO +CREATE TABLE [dbo].[Grant] ( + [Key] NVARCHAR (200) NOT NULL, + [Type] NVARCHAR (50) NULL, + [SubjectId] NVARCHAR (50) NULL, + [ClientId] NVARCHAR (50) NOT NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [ExpirationDate] DATETIME2 (7) NULL, + [Data] NVARCHAR (MAX) NOT NULL, + CONSTRAINT [PK_Grant] PRIMARY KEY CLUSTERED ([Key] ASC) +); + + +GO +PRINT N'Creating [dbo].[Grant].[IX_Grant_SubjectId_ClientId_Type]...'; + + +GO +CREATE NONCLUSTERED INDEX [IX_Grant_SubjectId_ClientId_Type] + ON [dbo].[Grant]([SubjectId] ASC, [ClientId] ASC, [Type] ASC); + + +GO +PRINT N'Creating [dbo].[Group]...'; + + +GO +CREATE TABLE [dbo].[Group] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [OrganizationId] UNIQUEIDENTIFIER NOT NULL, + [Name] NVARCHAR (50) NOT NULL, + [AccessAll] BIT NOT NULL, + [ExternalId] NVARCHAR (300) NULL, + [CreationDate] DATETIME NOT NULL, + [RevisionDate] DATETIME NOT NULL, + CONSTRAINT [PK_Group] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[GroupUser]...'; + + +GO +CREATE TABLE [dbo].[GroupUser] ( + [GroupId] UNIQUEIDENTIFIER NOT NULL, + [OrganizationUserId] UNIQUEIDENTIFIER NOT NULL, + CONSTRAINT [PK_GroupUser] PRIMARY KEY CLUSTERED ([GroupId] ASC, [OrganizationUserId] ASC) +); + + +GO +PRINT N'Creating [dbo].[Installation]...'; + + +GO +CREATE TABLE [dbo].[Installation] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Email] NVARCHAR (50) NOT NULL, + [Key] VARCHAR (150) NOT NULL, + [Enabled] BIT NOT NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Installation] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[Organization]...'; + + +GO +CREATE TABLE [dbo].[Organization] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Name] NVARCHAR (50) NOT NULL, + [BusinessName] NVARCHAR (50) NULL, + [BillingEmail] NVARCHAR (50) NOT NULL, + [Plan] NVARCHAR (50) NOT NULL, + [PlanType] TINYINT NOT NULL, + [Seats] SMALLINT NULL, + [MaxCollections] SMALLINT NULL, + [UseGroups] BIT NOT NULL, + [UseDirectory] BIT NOT NULL, + [UseTotp] BIT NOT NULL, + [SelfHost] BIT NOT NULL, + [Storage] BIGINT NULL, + [MaxStorageGb] SMALLINT NULL, + [Gateway] TINYINT NULL, + [GatewayCustomerId] VARCHAR (50) NULL, + [GatewaySubscriptionId] VARCHAR (50) NULL, + [Enabled] BIT NOT NULL, + [LicenseKey] VARCHAR (100) NULL, + [ExpirationDate] DATETIME2 (7) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Organization] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[OrganizationUser]...'; + + +GO +CREATE TABLE [dbo].[OrganizationUser] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [OrganizationId] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NULL, + [Email] NVARCHAR (50) NULL, + [Key] VARCHAR (MAX) NULL, + [Status] TINYINT NOT NULL, + [Type] TINYINT NOT NULL, + [AccessAll] BIT NOT NULL, + [ExternalId] NVARCHAR (300) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_OrganizationUser] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[U2f]...'; + + +GO +CREATE TABLE [dbo].[U2f] ( + [Id] INT IDENTITY (1, 1) NOT NULL, + [UserId] UNIQUEIDENTIFIER NOT NULL, + [KeyHandle] VARCHAR (200) NULL, + [Challenge] VARCHAR (200) NOT NULL, + [AppId] VARCHAR (50) NOT NULL, + [Version] VARCHAR (20) NOT NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_U2f] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[User]...'; + + +GO +CREATE TABLE [dbo].[User] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Name] NVARCHAR (50) NULL, + [Email] NVARCHAR (50) NOT NULL, + [EmailVerified] BIT NOT NULL, + [MasterPassword] NVARCHAR (300) NOT NULL, + [MasterPasswordHint] NVARCHAR (50) NULL, + [Culture] NVARCHAR (10) NOT NULL, + [SecurityStamp] NVARCHAR (50) NOT NULL, + [TwoFactorProviders] NVARCHAR (MAX) NULL, + [TwoFactorRecoveryCode] NVARCHAR (32) NULL, + [EquivalentDomains] NVARCHAR (MAX) NULL, + [ExcludedGlobalEquivalentDomains] NVARCHAR (MAX) NULL, + [AccountRevisionDate] DATETIME2 (7) NOT NULL, + [Key] VARCHAR (MAX) NULL, + [PublicKey] VARCHAR (MAX) NULL, + [PrivateKey] VARCHAR (MAX) NULL, + [Premium] BIT NOT NULL, + [PremiumExpirationDate] DATETIME2 (7) NULL, + [Storage] BIGINT NULL, + [MaxStorageGb] SMALLINT NULL, + [Gateway] TINYINT NULL, + [GatewayCustomerId] VARCHAR (50) NULL, + [GatewaySubscriptionId] VARCHAR (50) NULL, + [LicenseKey] VARCHAR (100) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + [RevisionDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_User] PRIMARY KEY CLUSTERED ([Id] ASC) +); + + +GO +PRINT N'Creating [dbo].[User].[IX_User_Email]...'; + + +GO +CREATE UNIQUE NONCLUSTERED INDEX [IX_User_Email] + ON [dbo].[User]([Email] ASC); + + +GO +PRINT N'Creating [dbo].[FK_Cipher_Organization]...'; + + +GO +ALTER TABLE [dbo].[Cipher] WITH NOCHECK + ADD CONSTRAINT [FK_Cipher_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_Cipher_User]...'; + + +GO +ALTER TABLE [dbo].[Cipher] WITH NOCHECK + ADD CONSTRAINT [FK_Cipher_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_Collection_Organization]...'; + + +GO +ALTER TABLE [dbo].[Collection] WITH NOCHECK + ADD CONSTRAINT [FK_Collection_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_CollectionCipher_Cipher]...'; + + +GO +ALTER TABLE [dbo].[CollectionCipher] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionCipher_Cipher] FOREIGN KEY ([CipherId]) REFERENCES [dbo].[Cipher] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_CollectionCipher_Collection]...'; + + +GO +ALTER TABLE [dbo].[CollectionCipher] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionCipher_Collection] FOREIGN KEY ([CollectionId]) REFERENCES [dbo].[Collection] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_CollectionGroup_Collection]...'; + + +GO +ALTER TABLE [dbo].[CollectionGroup] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionGroup_Collection] FOREIGN KEY ([CollectionId]) REFERENCES [dbo].[Collection] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_CollectionGroup_Group]...'; + + +GO +ALTER TABLE [dbo].[CollectionGroup] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionGroup_Group] FOREIGN KEY ([GroupId]) REFERENCES [dbo].[Group] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_CollectionUser_Collection]...'; + + +GO +ALTER TABLE [dbo].[CollectionUser] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionUser_Collection] FOREIGN KEY ([CollectionId]) REFERENCES [dbo].[Collection] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_CollectionUser_OrganizationUser]...'; + + +GO +ALTER TABLE [dbo].[CollectionUser] WITH NOCHECK + ADD CONSTRAINT [FK_CollectionUser_OrganizationUser] FOREIGN KEY ([OrganizationUserId]) REFERENCES [dbo].[OrganizationUser] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_Device_User]...'; + + +GO +ALTER TABLE [dbo].[Device] WITH NOCHECK + ADD CONSTRAINT [FK_Device_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_Folder_User]...'; + + +GO +ALTER TABLE [dbo].[Folder] WITH NOCHECK + ADD CONSTRAINT [FK_Folder_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_Group_Organization]...'; + + +GO +ALTER TABLE [dbo].[Group] WITH NOCHECK + ADD CONSTRAINT [FK_Group_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_GroupUser_Group]...'; + + +GO +ALTER TABLE [dbo].[GroupUser] WITH NOCHECK + ADD CONSTRAINT [FK_GroupUser_Group] FOREIGN KEY ([GroupId]) REFERENCES [dbo].[Group] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_GroupUser_OrganizationUser]...'; + + +GO +ALTER TABLE [dbo].[GroupUser] WITH NOCHECK + ADD CONSTRAINT [FK_GroupUser_OrganizationUser] FOREIGN KEY ([OrganizationUserId]) REFERENCES [dbo].[OrganizationUser] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_OrganizationUser_Organization]...'; + + +GO +ALTER TABLE [dbo].[OrganizationUser] WITH NOCHECK + ADD CONSTRAINT [FK_OrganizationUser_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id]) ON DELETE CASCADE; + + +GO +PRINT N'Creating [dbo].[FK_OrganizationUser_User]...'; + + +GO +ALTER TABLE [dbo].[OrganizationUser] WITH NOCHECK + ADD CONSTRAINT [FK_OrganizationUser_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]); + + +GO +PRINT N'Creating [dbo].[FK_U2f_User]...'; + + +GO +ALTER TABLE [dbo].[U2f] WITH NOCHECK + ADD CONSTRAINT [FK_U2f_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]); + + +GO +PRINT N'Creating [dbo].[CipherView]...'; + + +GO +CREATE VIEW [dbo].[CipherView] +AS +SELECT + * +FROM + [dbo].[Cipher] +GO +PRINT N'Creating [dbo].[CollectionView]...'; + + +GO +CREATE VIEW [dbo].[CollectionView] +AS +SELECT + * +FROM + [dbo].[Collection] +GO +PRINT N'Creating [dbo].[DeviceView]...'; + + +GO +CREATE VIEW [dbo].[DeviceView] +AS +SELECT + * +FROM + [dbo].[Device] +GO +PRINT N'Creating [dbo].[FolderView]...'; + + +GO +CREATE VIEW [dbo].[FolderView] +AS +SELECT + * +FROM + [dbo].[Folder] +GO +PRINT N'Creating [dbo].[GrantView]...'; + + +GO +CREATE VIEW [dbo].[GrantView] +AS +SELECT + * +FROM + [dbo].[Grant] +GO +PRINT N'Creating [dbo].[GroupView]...'; + + +GO +CREATE VIEW [dbo].[GroupView] +AS +SELECT + * +FROM + [dbo].[Group] +GO +PRINT N'Creating [dbo].[InstallationView]...'; + + +GO +CREATE VIEW [dbo].[InstallationView] +AS +SELECT + * +FROM + [dbo].[Installation] +GO +PRINT N'Creating [dbo].[OrganizationUserOrganizationDetailsView]...'; + + +GO +CREATE VIEW [dbo].[OrganizationUserOrganizationDetailsView] +AS +SELECT + OU.[UserId], + OU.[OrganizationId], + O.[Name], + O.[Enabled], + O.[UseGroups], + O.[UseDirectory], + O.[UseTotp], + O.[Seats], + O.[MaxCollections], + O.[MaxStorageGb], + OU.[Key], + OU.[Status], + OU.[Type] +FROM + [dbo].[OrganizationUser] OU +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] +GO +PRINT N'Creating [dbo].[OrganizationUserUserDetailsView]...'; + + +GO +CREATE VIEW [dbo].[OrganizationUserUserDetailsView] +AS +SELECT + OU.[Id], + OU.[UserId], + OU.[OrganizationId], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + OU.[Status], + OU.[Type], + OU.[AccessAll], + OU.[ExternalId] +FROM + [dbo].[OrganizationUser] OU +LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] +GO +PRINT N'Creating [dbo].[OrganizationUserView]...'; + + +GO +CREATE VIEW [dbo].[OrganizationUserView] +AS +SELECT + * +FROM + [dbo].[OrganizationUser] +GO +PRINT N'Creating [dbo].[OrganizationView]...'; + + +GO +CREATE VIEW [dbo].[OrganizationView] +AS +SELECT + * +FROM + [dbo].[Organization] +GO +PRINT N'Creating [dbo].[U2fView]...'; + + +GO +CREATE VIEW [dbo].[U2fView] +AS +SELECT + * +FROM + [dbo].[U2f] +GO +PRINT N'Creating [dbo].[UserView]...'; + + +GO +CREATE VIEW [dbo].[UserView] +AS +SELECT + * +FROM + [dbo].[User] +GO +PRINT N'Creating [dbo].[CipherDetails]...'; + + +GO +CREATE 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 + C.[Favorites] IS NULL + OR JSON_VALUE(C.[Favorites], CONCAT('$."', @UserId, '"')) IS NULL + THEN 0 + ELSE 1 + END [Favorite], + CASE WHEN + C.[Folders] IS NULL + THEN NULL + ELSE TRY_CONVERT(UNIQUEIDENTIFIER, JSON_VALUE(C.[Folders], CONCAT('$."', @UserId, '"'))) + END [FolderId] +FROM + [dbo].[Cipher] C +GO +PRINT N'Creating [dbo].[UserCipherDetails]...'; + + +GO +CREATE FUNCTION [dbo].[UserCipherDetails](@UserId UNIQUEIDENTIFIER) +RETURNS TABLE +AS RETURN +SELECT + C.*, + CASE + WHEN C.[UserId] IS NOT NULL OR OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 1 + ELSE 0 + END [Edit], + CASE + WHEN C.[UserId] IS NULL AND O.[UseTotp] = 1 THEN 1 + ELSE 0 + END [OrganizationUseTotp] +FROM + [dbo].[CipherDetails](@UserId) C +LEFT JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] +LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId +LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] +LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] +LEFT JOIN + [dbo].[GroupUser] GU ON C.[UserId] IS NULL AND 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] +WHERE + C.[UserId] = @UserId + OR ( + C.[UserId] IS NULL + 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 +PRINT N'Creating [dbo].[Cipher_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[CipherView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Cipher_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[CipherView] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[Cipher_ReadCanEditByIdUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_ReadCanEditByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @CanEdit BIT + + ;WITH [CTE] AS ( + SELECT + CASE + WHEN C.[UserId] IS NOT NULL OR OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 1 + ELSE 0 + END [Edit] + FROM + [dbo].[CipherDetails](@UserId) C + LEFT JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[GroupUser] GU ON C.[UserId] IS NULL AND 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + C.Id = @Id + AND ( + C.[UserId] = @UserId + OR ( + C.[UserId] IS NULL + 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 + ) + ) + ) + ) + SELECT + @CanEdit = CASE + WHEN COUNT(1) > 0 THEN 1 + ELSE 0 + END + FROM + [CTE] + WHERE + [Edit] = 1 + + SELECT @CanEdit +END +GO +PRINT N'Creating [dbo].[CipherDetails_ReadByIdUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[CipherDetails_ReadByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT TOP 1 + * + FROM + [dbo].[UserCipherDetails](@UserId) + WHERE + [Id] = @Id + ORDER BY + [Edit] DESC +END +GO +PRINT N'Creating [dbo].[CipherDetails_ReadByTypeUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[CipherDetails_ReadByTypeUserId] + @Type TINYINT, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserCipherDetails](@UserId) + WHERE + [Type] = @Type +END +GO +PRINT N'Creating [dbo].[CipherDetails_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[CipherDetails_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserCipherDetails](@UserId) +END +GO +PRINT N'Creating [dbo].[CipherDetails_ReadByUserIdHasCollection]...'; + + +GO +CREATE PROCEDURE [dbo].[CipherDetails_ReadByUserIdHasCollection] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.*, + CASE + WHEN C.[UserId] IS NOT NULL OR OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 1 + ELSE 0 + END [Edit] + FROM + [dbo].[CipherDetails](@UserId) C + INNER JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[GroupUser] GU ON C.[UserId] IS NULL AND 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + 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 + ) +END +GO +PRINT N'Creating [dbo].[Collection_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_Create] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Collection] + ( + [Id], + [OrganizationId], + [Name], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @OrganizationId, + @Name, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[Collection_CreateWithGroups]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_CreateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Create] @Id, @OrganizationId, @Name, @CreationDate, @RevisionDate + + ;WITH [AvailableGroupsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Group] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly] + ) + SELECT + @Id, + [Id], + [ReadOnly] + FROM + @Groups + WHERE + [Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) +END +GO +PRINT N'Creating [dbo].[Collection_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[CollectionGroup] + WHERE + [CollectionId] = @Id + + DELETE + FROM + [dbo].[Collection] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Collection_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[CollectionView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Collection_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[CollectionView] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[Collection_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.* + 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 + ) +END +GO +PRINT N'Creating [dbo].[Collection_ReadCountByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_ReadCountByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[Collection_ReadWithGroupsById]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_ReadWithGroupsById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_ReadById] @Id + + SELECT + [GroupId] [Id], + [ReadOnly] + FROM + [dbo].[CollectionGroup] + WHERE + [CollectionId] = @Id +END +GO +PRINT N'Creating [dbo].[Collection_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_Update] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Collection] + SET + [OrganizationId] = @OrganizationId, + [Name] = @Name, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Collection_UpdateWithGroups]...'; + + +GO +CREATE PROCEDURE [dbo].[Collection_UpdateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @CreationDate, @RevisionDate + + ;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 VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + -- TODO: Update user revision date times that this affects +END +GO +PRINT N'Creating [dbo].[CollectionCipher_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + SC.* + FROM + [dbo].[CollectionCipher] SC + INNER JOIN + [dbo].[Collection] S ON S.[Id] = SC.[CollectionId] + WHERE + S.[OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[CollectionCipher_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + CC.* + FROM + [dbo].[CollectionCipher] CC + INNER JOIN + [dbo].[Collection] S ON S.[Id] = CC.[CollectionId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = S.[OrganizationId] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[CollectionId] = S.[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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL + ) +END +GO +PRINT N'Creating [dbo].[CollectionCipher_ReadByUserIdCipherId]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_ReadByUserIdCipherId] + @UserId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + CC.* + FROM + [dbo].[CollectionCipher] CC + INNER JOIN + [dbo].[Collection] S ON S.[Id] = CC.[CollectionId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = S.[OrganizationId] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[CollectionId] = S.[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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + CC.[CipherId] = @CipherId + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL + ) +END +GO +PRINT N'Creating [dbo].[CollectionUserDetails_ReadByCollectionId]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + OU.[Id] AS [OrganizationUserId], + CASE + WHEN OU.[AccessAll] = 1 OR G.[AccessAll] = 1 THEN 1 + ELSE 0 + END [AccessAll], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + OU.[Status], + OU.[Type], + CASE + WHEN OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 0 + ELSE 1 + END [ReadOnly] + FROM + [dbo].[OrganizationUser] OU + LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId + WHERE + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR ( + OU.[OrganizationId] = @OrganizationId + AND ( + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) + ) +END +GO +PRINT N'Creating [dbo].[Device_ClearPushTokenById]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_ClearPushTokenById] + @Id NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Device] + SET + [PushToken] = NULL + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Device_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_Create] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Type TINYINT, + @Identifier NVARCHAR(50), + @PushToken NVARCHAR(255), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Device] + ( + [Id], + [UserId], + [Name], + [Type], + [Identifier], + [PushToken], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @UserId, + @Name, + @Type, + @Identifier, + @PushToken, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[Device_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Device] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Device_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[DeviceView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Device_ReadByIdentifier]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_ReadByIdentifier] + @Identifier NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[DeviceView] + WHERE + [Identifier] = @Identifier +END +GO +PRINT N'Creating [dbo].[Device_ReadByIdentifierUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_ReadByIdentifierUserId] + @UserId UNIQUEIDENTIFIER, + @Identifier NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[DeviceView] + WHERE + [UserId] = @UserId + AND [Identifier] = @Identifier +END +GO +PRINT N'Creating [dbo].[Device_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[DeviceView] + WHERE + [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[Device_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Device_Update] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Type TINYINT, + @Identifier NVARCHAR(50), + @PushToken NVARCHAR(255), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Device] + SET + [UserId] = @UserId, + [Name] = @Name, + [Type] = @Type, + [Identifier] = @Identifier, + [PushToken] = @PushToken, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Folder_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Folder_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[FolderView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Folder_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Folder_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[FolderView] + WHERE + [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[Grant_DeleteByKey]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_DeleteByKey] + @Key NVARCHAR(200) +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Grant] + WHERE + [Key] = @Key +END +GO +PRINT N'Creating [dbo].[Grant_DeleteBySubjectIdClientId]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_DeleteBySubjectIdClientId] + @SubjectId NVARCHAR(50), + @ClientId NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Grant] + WHERE + [SubjectId] = @SubjectId + AND [ClientId] = @ClientId +END +GO +PRINT N'Creating [dbo].[Grant_DeleteBySubjectIdClientIdType]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_DeleteBySubjectIdClientIdType] + @SubjectId NVARCHAR(50), + @ClientId NVARCHAR(50), + @Type NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Grant] + WHERE + [SubjectId] = @SubjectId + AND [ClientId] = @ClientId + AND [Type] = @Type +END +GO +PRINT N'Creating [dbo].[Grant_ReadByKey]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_ReadByKey] + @Key NVARCHAR(200) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[GrantView] + WHERE + [Key] = @Key +END +GO +PRINT N'Creating [dbo].[Grant_ReadBySubjectId]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_ReadBySubjectId] + @SubjectId NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[GrantView] + WHERE + [SubjectId] = @SubjectId +END +GO +PRINT N'Creating [dbo].[Grant_Save]...'; + + +GO +CREATE PROCEDURE [dbo].[Grant_Save] + @Key NVARCHAR(200), + @Type NVARCHAR(50), + @SubjectId NVARCHAR(50), + @ClientId NVARCHAR(50), + @CreationDate DATETIME2, + @ExpirationDate DATETIME2, + @Data NVARCHAR(MAX) +AS +BEGIN + SET NOCOUNT ON + + MERGE + [dbo].[Grant] AS [Target] + USING + ( + VALUES + ( + @Key, + @Type, + @SubjectId, + @ClientId, + @CreationDate, + @ExpirationDate, + @Data + ) + ) AS [Source] + ( + [Key], + [Type], + [SubjectId], + [ClientId], + [CreationDate], + [ExpirationDate], + [Data] + ) + ON + [Target].[Key] = [Source].[Key] + WHEN MATCHED THEN + UPDATE + SET + [Type] = [Source].[Type], + [SubjectId] = [Source].[SubjectId], + [ClientId] = [Source].[ClientId], + [CreationDate] = [Source].[CreationDate], + [ExpirationDate] = [Source].[ExpirationDate], + [Data] = [Source].[Data] + WHEN NOT MATCHED THEN + INSERT + ( + [Key], + [Type], + [SubjectId], + [ClientId], + [CreationDate], + [ExpirationDate], + [Data] + ) + VALUES + ( + [Source].[Key], + [Source].[Type], + [Source].[SubjectId], + [Source].[ClientId], + [Source].[CreationDate], + [Source].[ExpirationDate], + [Source].[Data] + ) + ; +END +GO +PRINT N'Creating [dbo].[Group_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_Create] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Group] + ( + [Id], + [OrganizationId], + [Name], + [AccessAll], + [ExternalId], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @OrganizationId, + @Name, + @AccessAll, + @ExternalId, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[Group_CreateWithCollections]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_CreateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] 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] + ) + SELECT + [Id], + @Id, + [ReadOnly] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) +END +GO +PRINT N'Creating [dbo].[Group_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Group] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Group_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[GroupView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Group_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[GroupView] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[Group_ReadWithCollectionsById]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_ReadWithCollectionsById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Group_ReadById] @Id + + SELECT + [CollectionId] [Id], + [ReadOnly] + FROM + [dbo].[CollectionGroup] + WHERE + [GroupId] = @Id +END +GO +PRINT N'Creating [dbo].[Group_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_Update] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Group] + SET + [OrganizationId] = @OrganizationId, + [Name] = @Name, + [AccessAll] = @AccessAll, + [ExternalId] = @ExternalId, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Group_UpdateWithCollections]...'; + + +GO +CREATE PROCEDURE [dbo].[Group_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] 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 VALUES + ( + [Source].[Id], + @Id, + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @Id THEN + DELETE + ; + + -- TODO: Update user revision date times that this affects +END +GO +PRINT N'Creating [dbo].[GroupUser_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUser_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + GU.* + FROM + [dbo].[GroupUser] GU + INNER JOIN + [dbo].[Group] G ON G.[Id] = GU.[GroupId] + WHERE + G.[OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[GroupUser_ReadGroupIdsByOrganizationUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUser_ReadGroupIdsByOrganizationUserId] + @OrganizationUserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + [GroupId] + FROM + [dbo].[GroupUser] + WHERE + [OrganizationUserId] = @OrganizationUserId +END +GO +PRINT N'Creating [dbo].[GroupUser_UpdateUsers]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUser_UpdateUsers] + @GroupId UNIQUEIDENTIFIER, + @OrganizationUserIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Group] + WHERE + [Id] = @GroupId + ) + + ;WITH [AvailableUsersCTE] AS( + SELECT + [Id] + FROM + [dbo].[OrganizationUser] + WHERE + [OrganizationId] = @OrgId + ) + MERGE + [dbo].[GroupUser] AS [Target] + USING + @OrganizationUserIds AS [Source] + ON + [Target].[GroupId] = @GroupId + AND [Target].[OrganizationUserId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN + INSERT VALUES + ( + @GroupId, + [Source].[Id] + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @GroupId + AND [Target].[OrganizationUserId] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN + DELETE + ; + + -- TODO: Bump account revision date for all @OrganizationUserIds +END +GO +PRINT N'Creating [dbo].[GroupUserDetails_ReadByGroupId]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUserDetails_ReadByGroupId] + @GroupId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + OU.[Id] AS [OrganizationUserId], + OU.[AccessAll], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + OU.[Status], + OU.[Type] + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[GroupUser] GU ON GU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] + WHERE + GU.[GroupId] = @GroupId +END +GO +PRINT N'Creating [dbo].[Installation_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Installation_Create] + @Id UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(150), + @Enabled BIT, + @CreationDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Installation] + ( + [Id], + [Email], + [Key], + [Enabled], + [CreationDate] + ) + VALUES + ( + @Id, + @Email, + @Key, + @Enabled, + @CreationDate + ) +END +GO +PRINT N'Creating [dbo].[Installation_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Installation_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Installation] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Installation_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Installation_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[InstallationView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Installation_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Installation_Update] + @Id UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(150), + @Enabled BIT, + @CreationDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Installation] + SET + [Email] = @Email, + [Key] = @Key, + [Enabled] = @Enabled, + [CreationDate] = @CreationDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Organization_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseTotp], + [SelfHost], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseTotp, + @SelfHost, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[Organization_Read]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_Read] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationView] +END +GO +PRINT N'Creating [dbo].[Organization_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Organization_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + O.* + FROM + [dbo].[OrganizationView] O + INNER JOIN + [dbo].[OrganizationUser] OU ON O.[Id] = OU.[OrganizationId] + WHERE + OU.[UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[Organization_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) + +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseTotp] = @UseTotp, + [SelfHost] = @SelfHost, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Organization_UpdateStorage]...'; + + +GO +CREATE PROCEDURE [dbo].[Organization_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + [dbo].[Cipher] + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [dbo].[Cipher] C + LEFT JOIN + [CTE] ON C.[Id] = [CTE].[Id] + WHERE + C.[OrganizationId] = @Id + AND C.[Attachments] IS NOT NULL + + UPDATE + [dbo].[Organization] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[OrganizationUser_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_Create] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(MAX), + @Status TINYINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[OrganizationUser] + ( + [Id], + [OrganizationId], + [UserId], + [Email], + [Key], + [Status], + [Type], + [AccessAll], + [ExternalId], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @OrganizationId, + @UserId, + @Email, + @Key, + @Status, + @Type, + @AccessAll, + @ExternalId, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[OrganizationUser_CreateWithCollections]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_CreateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(MAX), + @Status TINYINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Create] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionUser] + ( + [CollectionId], + [OrganizationUserId], + [ReadOnly] + ) + SELECT + [Id], + @Id, + [ReadOnly] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) +END +GO +PRINT N'Creating [dbo].[OrganizationUser_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[CollectionUser] + WHERE + [OrganizationUserId] = @Id + + DELETE + FROM + [dbo].[GroupUser] + WHERE + [OrganizationUserId] = @Id + + DELETE + FROM + [dbo].[OrganizationUser] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER, + @Type TINYINT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserView] + WHERE + [OrganizationId] = @OrganizationId + AND (@Type IS NULL OR [Type] = @Type) +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadByOrganizationIdEmail]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationIdEmail] + @OrganizationId UNIQUEIDENTIFIER, + @Email NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserView] + WHERE + [OrganizationId] = @OrganizationId + AND [Email] = @Email +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadByOrganizationIdUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationIdUserId] + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserView] + WHERE + [OrganizationId] = @OrganizationId + AND [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserView] + WHERE + [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadCountByFreeOrganizationAdminUser]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByFreeOrganizationAdminUser] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[Organization] O ON O.Id = OU.[OrganizationId] + WHERE + OU.[UserId] = @UserId + AND OU.[Type] < 2 -- Owner or Admin + AND O.[PlanType] = 0 -- Free +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadCountByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] OU + WHERE + OU.[UserId] = @UserId + AND OU.[Type] = 0 +END +GO +PRINT N'Creating [dbo].[OrganizationUser_ReadWithCollectionsById]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_ReadWithCollectionsById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [OrganizationUser_ReadById] @Id + + SELECT + CU.[CollectionId] Id, + CU.[ReadOnly] + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = [OU].[Id] + WHERE + [OrganizationUserId] = @Id +END +GO +PRINT N'Creating [dbo].[OrganizationUserOrganizationDetails_ReadByUserIdStatus]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUserOrganizationDetails_ReadByUserIdStatus] + @UserId UNIQUEIDENTIFIER, + @Status TINYINT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserOrganizationDetailsView] + WHERE + [UserId] = @UserId + AND (@Status IS NULL OR [Status] = @Status) +END +GO +PRINT N'Creating [dbo].[OrganizationUserUserDetails_ReadByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUserUserDetails_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserUserDetailsView] + WHERE + [OrganizationId] = @OrganizationId +END +GO +PRINT N'Creating [dbo].[U2f_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[U2f_Create] + @Id INT, + @UserId UNIQUEIDENTIFIER, + @KeyHandle VARCHAR(200), + @Challenge VARCHAR(200), + @AppId VARCHAR(50), + @Version VARCHAR(20), + @CreationDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[U2f] + ( + [UserId], + [KeyHandle], + [Challenge], + [AppId], + [Version], + [CreationDate] + ) + VALUES + ( + @UserId, + @KeyHandle, + @Challenge, + @AppId, + @Version, + @CreationDate + ) +END +GO +PRINT N'Creating [dbo].[U2f_DeleteByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[U2f_DeleteByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[U2f] + WHERE + [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[U2f_ReadByUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[U2f_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[U2fView] + WHERE + [UserId] = @UserId +END +GO +PRINT N'Creating [dbo].[User_BumpAccountRevisionDate]...'; + + +GO +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDate] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [User] + SET + [AccountRevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_BumpAccountRevisionDateByOrganizationId]...'; + + +GO +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + WHERE + OU.[OrganizationId] = @OrganizationId + AND OU.[Status] = 2 -- Confirmed +END +GO +PRINT N'Creating [dbo].[User_BumpAccountRevisionDateByOrganizationUserId]...'; + + +GO +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] + @OrganizationUserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + WHERE + OU.[Id] = @OrganizationUserId + AND OU.[Status] = 2 -- Confirmed +END +GO +PRINT N'Creating [dbo].[User_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[User_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[User] + ( + [Id], + [Name], + [Email], + [EmailVerified], + [MasterPassword], + [MasterPasswordHint], + [Culture], + [SecurityStamp], + [TwoFactorProviders], + [TwoFactorRecoveryCode], + [EquivalentDomains], + [ExcludedGlobalEquivalentDomains], + [AccountRevisionDate], + [Key], + [PublicKey], + [PrivateKey], + [Premium], + [PremiumExpirationDate], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [LicenseKey], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @Email, + @EmailVerified, + @MasterPassword, + @MasterPasswordHint, + @Culture, + @SecurityStamp, + @TwoFactorProviders, + @TwoFactorRecoveryCode, + @EquivalentDomains, + @ExcludedGlobalEquivalentDomains, + @AccountRevisionDate, + @Key, + @PublicKey, + @PrivateKey, + @Premium, + @PremiumExpirationDate, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @LicenseKey, + @CreationDate, + @RevisionDate + ) +END +GO +PRINT N'Creating [dbo].[User_DeleteById]...'; + + +GO +CREATE 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 organization users + DELETE + FROM + [dbo].[OrganizationUser] + WHERE + [UserId] = @Id + AND [Type] != 0 -- 0 = owner + + -- Finally, delete the user + DELETE + FROM + [dbo].[User] + WHERE + [Id] = @Id + + COMMIT TRANSACTION User_DeleteById +END +GO +PRINT N'Creating [dbo].[User_ReadAccountRevisionDateById]...'; + + +GO + +CREATE PROCEDURE [dbo].[User_ReadAccountRevisionDateById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + [AccountRevisionDate] + FROM + [dbo].[User] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_ReadByEmail]...'; + + +GO +CREATE PROCEDURE [dbo].[User_ReadByEmail] + @Email NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserView] + WHERE + [Email] = @Email +END +GO +PRINT N'Creating [dbo].[User_ReadById]...'; + + +GO +CREATE PROCEDURE [dbo].[User_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserView] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_ReadPublicKeyById]...'; + + +GO +CREATE PROCEDURE [dbo].[User_ReadPublicKeyById] + @Id NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + [PublicKey] + FROM + [dbo].[User] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[User_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[User] + SET + [Name] = @Name, + [Email] = @Email, + [EmailVerified] = @EmailVerified, + [MasterPassword] = @MasterPassword, + [MasterPasswordHint] = @MasterPasswordHint, + [Culture] = @Culture, + [SecurityStamp] = @SecurityStamp, + [TwoFactorProviders] = @TwoFactorProviders, + [TwoFactorRecoveryCode] = @TwoFactorRecoveryCode, + [EquivalentDomains] = @EquivalentDomains, + [ExcludedGlobalEquivalentDomains] = @ExcludedGlobalEquivalentDomains, + [AccountRevisionDate] = @AccountRevisionDate, + [Key] = @Key, + [PublicKey] = @PublicKey, + [PrivateKey] = @PrivateKey, + [Premium] = @Premium, + [PremiumExpirationDate] = @PremiumExpirationDate, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [LicenseKey] = @LicenseKey, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_UpdateKeys]...'; + + +GO +CREATE PROCEDURE [dbo].[User_UpdateKeys] + @Id UNIQUEIDENTIFIER, + @SecurityStamp NVARCHAR(50), + @Key NVARCHAR(MAX), + @PrivateKey VARCHAR(MAX), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[User] + SET + [SecurityStamp] = @SecurityStamp, + [Key] = @Key, + [PrivateKey] = @PrivateKey, + [RevisionDate] = @RevisionDate, + [AccountRevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[User_UpdateStorage]...'; + + +GO +CREATE PROCEDURE [dbo].[User_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + [dbo].[Cipher] + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [dbo].[Cipher] C + LEFT JOIN + [CTE] ON C.[Id] = [CTE].[Id] + WHERE + C.[UserId] = @Id + AND C.[Attachments] IS NOT NULL + + UPDATE + [dbo].[User] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[Cipher_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_Create] + @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) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Cipher] + ( + [Id], + [UserId], + [OrganizationId], + [Type], + [Data], + [Favorites], + [Folders], + [Attachments], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @UserId, + @OrganizationId, + @Type, + @Data, + @Favorites, + @Folders, + @Attachments, + @CreationDate, + @RevisionDate + ) + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_Delete]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_Delete] + @Ids AS [dbo].[GuidIdArray] READONLY, + @UserId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #Temp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NULL, + [OrganizationId] UNIQUEIDENTIFIER NULL, + [Attachments] BIT NOT NULL + ) + + INSERT INTO #Temp + SELECT + [Id], + [UserId], + [OrganizationId], + CASE WHEN [Attachments] IS NULL THEN 0 ELSE 1 END + FROM + [dbo].[UserCipherDetails](@UserId) + WHERE + [Edit] = 1 + AND [Id] IN (SELECT * FROM @Ids) + + -- Delete ciphers + DELETE + FROM + [dbo].[Cipher] + WHERE + [Id] IN (SELECT [Id] FROM #Temp) + + -- Cleanup orgs + DECLARE @OrgId UNIQUEIDENTIFIER + DECLARE [OrgCursor] CURSOR FORWARD_ONLY FOR + SELECT + [OrganizationId] + FROM + #Temp + WHERE + [OrganizationId] IS NOT NULL + GROUP BY + [OrganizationId] + OPEN [OrgCursor] + FETCH NEXT FROM [OrgCursor] INTO @OrgId + WHILE @@FETCH_STATUS = 0 BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrgId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId + FETCH NEXT FROM [OrgCursor] INTO @OrgId + END + CLOSE [OrgCursor] + DEALLOCATE [OrgCursor] + + -- Cleanup user + DECLARE @UserCiphersWithStorageCount INT + SELECT + @UserCiphersWithStorageCount = COUNT(1) + FROM + #Temp + WHERE + [UserId] IS NOT NULL + AND [Attachments] = 1 + + IF @UserCiphersWithStorageCount > 0 + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + END + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + + DROP TABLE #Temp +END +GO +PRINT N'Creating [dbo].[Cipher_DeleteAttachment]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_DeleteAttachment] + @Id UNIQUEIDENTIFIER, + @AttachmentId VARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + DECLARE @AttachmentIdKey VARCHAR(50) = CONCAT('"', @AttachmentId, '"') + DECLARE @AttachmentIdPath VARCHAR(50) = CONCAT('$.', @AttachmentIdKey) + + DECLARE @UserId UNIQUEIDENTIFIER + DECLARE @OrganizationId UNIQUEIDENTIFIER + + SELECT + @UserId = [UserId], + @OrganizationId = [OrganizationId] + FROM + [dbo].[Cipher] + WHERE [Id] = @Id + + UPDATE + [dbo].[Cipher] + SET + [Attachments] = JSON_MODIFY([Attachments], @AttachmentIdPath, NULL) + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER + DECLARE @OrganizationId UNIQUEIDENTIFIER + DECLARE @Attachments BIT + + SELECT TOP 1 + @UserId = [UserId], + @OrganizationId = [OrganizationId], + @Attachments = CASE WHEN [Attachments] IS NOT NULL THEN 1 ELSE 0 END + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + DELETE + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + END + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + END + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_Move]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_Move] + @Ids AS [dbo].[GuidIdArray] READONLY, + @FolderId AS UNIQUEIDENTIFIER, + @UserId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserIdKey VARCHAR(50) = CONCAT('"', @UserId, '"') + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$.', @UserIdKey) + + ;WITH [IdsToMoveCTE] AS ( + SELECT + [Id] + FROM + [dbo].[UserCipherDetails](@UserId) + WHERE + [Edit] = 1 + AND [Id] IN (SELECT * FROM @Ids) + ) + UPDATE + [dbo].[Cipher] + SET + [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 + WHERE + [Id] IN (SELECT * FROM [IdsToMoveCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + -- TODO: What if some that were updated were organization ciphers? Then bump by org ids. +END +GO +PRINT N'Creating [dbo].[Cipher_Update]...'; + + +GO +CREATE 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) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Cipher] + SET + [UserId] = @UserId, + [OrganizationId] = @OrganizationId, + [Type] = @Type, + [Data] = @Data, + [Favorites] = @Favorites, + [Folders] = @Folders, + [Attachments] = @Attachments, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_UpdateAttachment]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_UpdateAttachment] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @AttachmentId VARCHAR(50), + @AttachmentData NVARCHAR(MAX) +AS +BEGIN + SET NOCOUNT ON + + DECLARE @AttachmentIdKey VARCHAR(50) = CONCAT('"', @AttachmentId, '"') + DECLARE @AttachmentIdPath VARCHAR(50) = CONCAT('$.', @AttachmentIdKey) + + UPDATE + [dbo].[Cipher] + SET + [Attachments] = + CASE + WHEN [Attachments] IS NULL THEN + CONCAT('{', @AttachmentIdKey, ':', @AttachmentData, '}') + ELSE + JSON_MODIFY([Attachments], @AttachmentIdPath, JSON_QUERY(@AttachmentData, '$')) + END + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_UpdatePartial]...'; + + +GO +CREATE PROCEDURE [dbo].[Cipher_UpdatePartial] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @FolderId UNIQUEIDENTIFIER, + @Favorite BIT +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserIdKey VARCHAR(50) = CONCAT('"', @UserId, '"') + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$.', @UserIdKey) + + UPDATE + [dbo].[Cipher] + SET + [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 + WHERE + [Id] = @Id + + IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[Cipher_UpdateWithCollections]...'; + + +GO +CREATE 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), + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Cipher] + SET + [UserId] = NULL, + [OrganizationId] = @OrganizationId, + [Data] = @Data, + [Attachments] = @Attachments, + [RevisionDate] = @RevisionDate + -- No need to update CreationDate, Favorites, Folders, or Type since that data will not change + WHERE + [Id] = @Id + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + S.[Id] + FROM + [dbo].[Collection] S + INNER JOIN + [Organization] O ON O.[Id] = S.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[CollectionId] = S.[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.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + ) + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Id], + @Id + FROM + @CollectionIds + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) + + IF @Attachments IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_UpdateStorage] @UserId + END + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO +PRINT N'Creating [dbo].[CipherDetails_Create]...'; + + +GO +CREATE 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 + @OrganizationUseTotp BIT -- not used +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] + ) + 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 + ) + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[CipherDetails_Update]...'; + + +GO +CREATE 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), -- not used + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @FolderId UNIQUEIDENTIFIER, + @Favorite BIT, + @Edit BIT, -- not used + @OrganizationUseTotp BIT -- not used +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, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO +PRINT N'Creating [dbo].[CollectionCipher_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_Create] + @CollectionId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + VALUES + ( + @CollectionId, + @CipherId + ) + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Cipher] WHERE [Id] = @CipherId) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END +END +GO +PRINT N'Creating [dbo].[CollectionCipher_Delete]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_Delete] + @CollectionId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[CollectionCipher] + WHERE + [CollectionId] = @CollectionId + AND [CipherId] = @CipherId + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Cipher] WHERE [Id] = @CipherId) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END +END +GO +PRINT N'Creating [dbo].[CollectionCipher_UpdateCollections]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollections] + @CipherId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Cipher] + WHERE + [Id] = @CipherId + ) + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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 + O.[Id] = @OrgId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL + ) + ) + MERGE + [dbo].[CollectionCipher] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId + AND [Target].[CollectionId] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + DELETE + ; + + IF @OrgId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId + END +END +GO +PRINT N'Creating [dbo].[CollectionCipher_UpdateCollectionsAdmin]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsAdmin] + @CipherId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + Id + FROM + [dbo].[Collection] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionCipher] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId THEN + DELETE + ; + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END +END +GO +PRINT N'Creating [dbo].[CollectionUser_Delete]...'; + + +GO +CREATE PROCEDURE [dbo].[CollectionUser_Delete] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationUserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = @CollectionId + AND [OrganizationUserId] = @OrganizationUserId + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId +END +GO +PRINT N'Creating [dbo].[Folder_Create]...'; + + +GO +CREATE PROCEDURE [dbo].[Folder_Create] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Folder] + ( + [Id], + [UserId], + [Name], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @UserId, + @Name, + @CreationDate, + @RevisionDate + ) + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO +PRINT N'Creating [dbo].[Folder_DeleteById]...'; + + +GO +CREATE PROCEDURE [dbo].[Folder_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER = (SELECT TOP 1 [UserId] FROM [dbo].[Folder] WHERE [Id] = @Id) + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$."', @UserId, '"') + + UPDATE + C + SET + C.[Folders] = JSON_MODIFY(C.[Folders], @UserIdPath, NULL) + FROM + [dbo].[Cipher] C + LEFT JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + WHERE + ( + C.[UserId] = @UserId + OR ( + C.[UserId] IS NULL + AND (OU.[AccessAll] = 1 OR CU.[CollectionId] IS NOT NULL) + ) + ) + AND C.[Folders] IS NOT NULL + AND JSON_VALUE(C.[Folders], @UserIdPath) = @Id + + DELETE + FROM + [dbo].[Folder] + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO +PRINT N'Creating [dbo].[Folder_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[Folder_Update] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Folder] + SET + [UserId] = @UserId, + [Name] = @Name, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO +PRINT N'Creating [dbo].[GroupUser_Delete]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUser_Delete] + @GroupId UNIQUEIDENTIFIER, + @OrganizationUserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[GroupUser] + WHERE + [GroupId] = @GroupId + AND [OrganizationUserId] = @OrganizationUserId + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId +END +GO +PRINT N'Creating [dbo].[GroupUser_UpdateGroups]...'; + + +GO +CREATE PROCEDURE [dbo].[GroupUser_UpdateGroups] + @OrganizationUserId UNIQUEIDENTIFIER, + @GroupIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[OrganizationUser] + WHERE + [Id] = @OrganizationUserId + ) + + ;WITH [AvailableGroupsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Group] + WHERE + [OrganizationId] = @OrgId + ) + MERGE + [dbo].[GroupUser] AS [Target] + USING + @GroupIds AS [Source] + ON + [Target].[GroupId] = [Source].[Id] + AND [Target].[OrganizationUserId] = @OrganizationUserId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @OrganizationUserId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[OrganizationUserId] = @OrganizationUserId + AND [Target].[GroupId] IN (SELECT [Id] FROM [AvailableGroupsCTE]) THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @OrganizationUserId +END +GO +PRINT N'Creating [dbo].[Organization_DeleteById]...'; + + +GO +CREATE 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 + [OrganizationId] = @Id + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION Organization_DeleteById_Ciphers + END + + DELETE + FROM + [dbo].[Organization] + WHERE + [Id] = @Id +END +GO +PRINT N'Creating [dbo].[OrganizationUser_Update]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_Update] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(MAX), + @Status TINYINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +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 + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO +PRINT N'Creating [dbo].[OrganizationUser_UpdateWithCollections]...'; + + +GO +CREATE PROCEDURE [dbo].[OrganizationUser_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @Key VARCHAR(MAX), + @Status TINYINT, + @Type TINYINT, + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[OrganizationUser_Update] @Id, @OrganizationId, @UserId, @Email, @Key, @Status, @Type, @AccessAll, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + Id + FROM + [dbo].[Collection] + WHERE + OrganizationId = @OrganizationId + ) + MERGE + [dbo].[CollectionUser] AS [Target] + USING + @Collections AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[OrganizationUserId] = @Id + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @Id, + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[OrganizationUserId] = @Id THEN + DELETE + ; +END +GO +PRINT N'Checking existing data against newly created constraints'; + + +GO +ALTER TABLE [dbo].[Cipher] WITH CHECK CHECK CONSTRAINT [FK_Cipher_Organization]; + +ALTER TABLE [dbo].[Cipher] WITH CHECK CHECK CONSTRAINT [FK_Cipher_User]; + +ALTER TABLE [dbo].[Collection] WITH CHECK CHECK CONSTRAINT [FK_Collection_Organization]; + +ALTER TABLE [dbo].[CollectionCipher] WITH CHECK CHECK CONSTRAINT [FK_CollectionCipher_Cipher]; + +ALTER TABLE [dbo].[CollectionCipher] WITH CHECK CHECK CONSTRAINT [FK_CollectionCipher_Collection]; + +ALTER TABLE [dbo].[CollectionGroup] WITH CHECK CHECK CONSTRAINT [FK_CollectionGroup_Collection]; + +ALTER TABLE [dbo].[CollectionGroup] WITH CHECK CHECK CONSTRAINT [FK_CollectionGroup_Group]; + +ALTER TABLE [dbo].[CollectionUser] WITH CHECK CHECK CONSTRAINT [FK_CollectionUser_Collection]; + +ALTER TABLE [dbo].[CollectionUser] WITH CHECK CHECK CONSTRAINT [FK_CollectionUser_OrganizationUser]; + +ALTER TABLE [dbo].[Device] WITH CHECK CHECK CONSTRAINT [FK_Device_User]; + +ALTER TABLE [dbo].[Folder] WITH CHECK CHECK CONSTRAINT [FK_Folder_User]; + +ALTER TABLE [dbo].[Group] WITH CHECK CHECK CONSTRAINT [FK_Group_Organization]; + +ALTER TABLE [dbo].[GroupUser] WITH CHECK CHECK CONSTRAINT [FK_GroupUser_Group]; + +ALTER TABLE [dbo].[GroupUser] WITH CHECK CHECK CONSTRAINT [FK_GroupUser_OrganizationUser]; + +ALTER TABLE [dbo].[OrganizationUser] WITH CHECK CHECK CONSTRAINT [FK_OrganizationUser_Organization]; + +ALTER TABLE [dbo].[OrganizationUser] WITH CHECK CHECK CONSTRAINT [FK_OrganizationUser_User]; + +ALTER TABLE [dbo].[U2f] WITH CHECK CHECK CONSTRAINT [FK_U2f_User]; + + +GO +PRINT N'Update complete.'; + + +GO diff --git a/src/Migrator/DbScripts/2017-08-22_00_LicenseCheckScripts.sql b/src/Migrator/DbScripts/2017-08-22_00_LicenseCheckScripts.sql new file mode 100644 index 000000000..86cea5a2e --- /dev/null +++ b/src/Migrator/DbScripts/2017-08-22_00_LicenseCheckScripts.sql @@ -0,0 +1,46 @@ +IF OBJECT_ID('[dbo].[Organization_Read]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Read] +END +GO + +IF OBJECT_ID('[dbo].[Organization_ReadByEnabled]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_ReadByEnabled] +END +GO + +CREATE PROCEDURE [dbo].[Organization_ReadByEnabled] +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationView] + WHERE + [Enabled] = 1 +END +GO + +IF OBJECT_ID('[dbo].[User_ReadByPremium]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_ReadByPremium] +END +GO + +CREATE PROCEDURE [dbo].[User_ReadByPremium] + @Premium BIT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserView] + WHERE + [Premium] = @Premium +END +GO diff --git a/src/Migrator/DbScripts/2017-08-30_00_CollectionWriteOnly.sql b/src/Migrator/DbScripts/2017-08-30_00_CollectionWriteOnly.sql new file mode 100644 index 000000000..f05f09635 --- /dev/null +++ b/src/Migrator/DbScripts/2017-08-30_00_CollectionWriteOnly.sql @@ -0,0 +1,224 @@ +IF OBJECT_ID('[dbo].[Collection_ReadByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_ReadByUserId] +END +GO + +IF OBJECT_ID('[dbo].[Cipher_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateWithCollections] +END +GO + +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollections] +END +GO + +CREATE PROCEDURE [dbo].[Collection_ReadByUserId] + @UserId UNIQUEIDENTIFIER, + @WriteOnly BIT +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.* + 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 + ) + AND ( + @WriteOnly = 0 + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR CG.[ReadOnly] = 0 + ) +END +GO + +CREATE 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), + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + SELECT -1 -- -1 = Failure + RETURN + END + + UPDATE + [dbo].[Cipher] + SET + [UserId] = NULL, + [OrganizationId] = @OrganizationId, + [Data] = @Data, + [Attachments] = @Attachments, + [RevisionDate] = @RevisionDate + -- No need to update CreationDate, Favorites, Folders, or Type since that data will not change + WHERE + [Id] = @Id + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Id], + @Id + FROM + @CollectionIds + WHERE + [Id] IN (SELECT [Id] FROM #AvailableCollections) + + IF @Attachments IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_UpdateStorage] @UserId + END + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + + SELECT 0 -- 0 = Success +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollections] + @CipherId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Cipher] + WHERE + [Id] = @CipherId + ) + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrgId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + ) + MERGE + [dbo].[CollectionCipher] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId + AND [Target].[CollectionId] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + DELETE + ; + + IF @OrgId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId + END +END +GO diff --git a/src/Migrator/DbScripts/2017-09-06_00_CipherDetails.sql b/src/Migrator/DbScripts/2017-09-06_00_CipherDetails.sql new file mode 100644 index 000000000..63aa54d2e --- /dev/null +++ b/src/Migrator/DbScripts/2017-09-06_00_CipherDetails.sql @@ -0,0 +1,180 @@ +IF OBJECT_ID('[dbo].[CipherDetails]') IS NOT NULL +BEGIN + DROP FUNCTION [dbo].[CipherDetails] +END +GO + +CREATE 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] +FROM + [dbo].[Cipher] C +GO + +IF OBJECT_ID('[dbo].[CipherDetails_ReadById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_ReadById] +END +GO + +CREATE PROCEDURE [dbo].[CipherDetails_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.*, + 1 [Edit], + CASE + WHEN O.[UseTotp] = 1 THEN 1 + ELSE 0 + END [OrganizationUseTotp] + FROM + [dbo].[CipherDetails](NULL) C + LEFT JOIN + [dbo].[Organization] O ON O.[Id] = C.[OrganizationId] + WHERE + C.[Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_ReadByUserIdHasCollection]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_ReadByUserIdHasCollection] +END +GO + +CREATE PROCEDURE [dbo].[CipherDetails_ReadByUserIdHasCollection] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.*, + CASE + WHEN C.[UserId] IS NOT NULL OR OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 1 + ELSE 0 + END [Edit], + CASE + WHEN C.[UserId] IS NULL AND O.[UseTotp] = 1 THEN 1 + ELSE 0 + END [OrganizationUseTotp] + FROM + [dbo].[CipherDetails](@UserId) C + INNER JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[GroupUser] GU ON C.[UserId] IS NULL AND 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + 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 + ) +END +GO + +IF OBJECT_ID('[dbo].[Cipher_ReadCanEditByIdUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_ReadCanEditByIdUserId] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_ReadCanEditByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @CanEdit BIT + + ;WITH [CTE] AS ( + SELECT + CASE + WHEN C.[UserId] IS NOT NULL OR OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 1 + ELSE 0 + END [Edit] + FROM + [dbo].[Cipher] C + LEFT JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + LEFT JOIN + [dbo].[GroupUser] GU ON C.[UserId] IS NULL AND 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + C.Id = @Id + AND ( + C.[UserId] = @UserId + OR ( + C.[UserId] IS NULL + 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 + ) + ) + ) + ) + SELECT + @CanEdit = CASE + WHEN COUNT(1) > 0 THEN 1 + ELSE 0 + END + FROM + [CTE] + WHERE + [Edit] = 1 + + SELECT @CanEdit +END +GO diff --git a/src/Migrator/DbScripts/2017-09-08_00_OrgUserCounts.sql b/src/Migrator/DbScripts/2017-09-08_00_OrgUserCounts.sql new file mode 100644 index 000000000..9e9a36021 --- /dev/null +++ b/src/Migrator/DbScripts/2017-09-08_00_OrgUserCounts.sql @@ -0,0 +1,48 @@ +IF OBJECT_ID('[dbo].[OrganizationUser_ReadCountByFreeOrganizationAdminUser]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadCountByFreeOrganizationAdminUser] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByFreeOrganizationAdminUser] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[Organization] O ON O.Id = OU.[OrganizationId] + WHERE + OU.[UserId] = @UserId + AND OU.[Type] < 2 -- Owner or Admin + AND O.[PlanType] = 0 -- Free + AND OU.[Status] = 2 -- 2 = Confirmed +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] OU + WHERE + OU.[UserId] = @UserId + AND OU.[Type] = 0 + AND OU.[Status] = 2 -- 2 = Confirmed +END +GO diff --git a/src/Migrator/DbScripts/2017-10-25_00_OrgUserUpdates.sql b/src/Migrator/DbScripts/2017-10-25_00_OrgUserUpdates.sql new file mode 100644 index 000000000..ff3d361f5 --- /dev/null +++ b/src/Migrator/DbScripts/2017-10-25_00_OrgUserUpdates.sql @@ -0,0 +1,396 @@ +IF OBJECT_ID('[dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationOwnerUser] +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_ReadCountByOnlyOwner]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadCountByOnlyOwner] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByOnlyOwner] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + ;WITH [OwnerCountCTE] AS + ( + SELECT + OU.[UserId], + COUNT(1) OVER (PARTITION BY OU.[OrganizationId]) [ConfirmedOwnerCount] + FROM + [dbo].[OrganizationUser] OU + WHERE + OU.[Type] = 0 -- 0 = Owner + AND OU.[Status] = 2 -- 2 = Confirmed + ) + SELECT + COUNT(1) + FROM + [OwnerCountCTE] OC + WHERE + OC.[UserId] = @UserId + AND OC.[ConfirmedOwnerCount] = 1 +END +GO + +IF OBJECT_ID('[dbo].[User_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_DeleteById] +END +GO + +CREATE 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 organization users + DELETE + FROM + [dbo].[OrganizationUser] + WHERE + [UserId] = @Id + + -- Finally, delete the user + DELETE + FROM + [dbo].[User] + WHERE + [Id] = @Id + + COMMIT TRANSACTION User_DeleteById +END +GO + +IF COL_LENGTH('[dbo].[Organization]', 'BusinessAddress1') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [BusinessAddress1] NVARCHAR(50) NULL, + [BusinessAddress2] NVARCHAR(50) NULL, + [BusinessAddress3] NVARCHAR(50) NULL, + [BusinessCountry] VARCHAR(2) NULL, + [BusinessTaxNumber] NVARCHAR(30) NULL +END +GO + +IF OBJECT_ID('[dbo].[Organization_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Create] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BusinessAddress1], + [BusinessAddress2], + [BusinessAddress3], + [BusinessCountry], + [BusinessTaxNumber], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseTotp], + [SelfHost], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BusinessAddress1, + @BusinessAddress2, + @BusinessAddress3, + @BusinessCountry, + @BusinessTaxNumber, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseTotp, + @SelfHost, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Update] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) + +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BusinessAddress1] = @BusinessAddress1, + [BusinessAddress2] = @BusinessAddress2, + [BusinessAddress3] = @BusinessAddress3, + [BusinessCountry] = @BusinessCountry, + [BusinessTaxNumber] = @BusinessTaxNumber, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseTotp] = @UseTotp, + [SelfHost] = @SelfHost, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Cipher_DeleteByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteByUserId] + @UserId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + + -- Delete ciphers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION Cipher_DeleteByUserId_Ciphers + + DELETE TOP(@BatchSize) + FROM + [dbo].[Cipher] + WHERE + [UserId] = @UserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION Cipher_DeleteByUserId_Ciphers + END + + -- Cleanup user + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO + +IF OBJECT_ID('[dbo].[Cipher_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteById] + @Id UNIQUEIDENTIFIER +WITH RECOMPILE +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER + DECLARE @OrganizationId UNIQUEIDENTIFIER + DECLARE @Attachments BIT + + SELECT TOP 1 + @UserId = [UserId], + @OrganizationId = [OrganizationId], + @Attachments = CASE WHEN [Attachments] IS NOT NULL THEN 1 ELSE 0 END + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + DELETE + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + END + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + END + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO diff --git a/src/Migrator/DbScripts/2017-11-06_00_FamilyPlanAdjustments.sql b/src/Migrator/DbScripts/2017-11-06_00_FamilyPlanAdjustments.sql new file mode 100644 index 000000000..c22c40977 --- /dev/null +++ b/src/Migrator/DbScripts/2017-11-06_00_FamilyPlanAdjustments.sql @@ -0,0 +1,250 @@ +IF COL_LENGTH('[dbo].[Organization]', 'UsersGetPremium') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [UsersGetPremium] BIT NULL +END +GO + +UPDATE + [dbo].[Organization] +SET + [UsersGetPremium] = (CASE WHEN [PlanType] = 5 OR [PlanType] = 4 THEN 1 ELSE 0 END) +GO + +UPDATE + [dbo].[Organization] +SET + [Plan] = 'Families' +WHERE + [PlanType] = 1 +GO + +ALTER TABLE + [dbo].[Organization] +ALTER COLUMN + [UsersGetPremium] BIT NOT NULL +GO + +IF OBJECT_ID('[dbo].[Organization_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Create] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BusinessAddress1], + [BusinessAddress2], + [BusinessAddress3], + [BusinessCountry], + [BusinessTaxNumber], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseTotp], + [SelfHost], + [UsersGetPremium], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BusinessAddress1, + @BusinessAddress2, + @BusinessAddress3, + @BusinessCountry, + @BusinessTaxNumber, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseTotp, + @SelfHost, + @UsersGetPremium, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Update] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseTotp BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BusinessAddress1] = @BusinessAddress1, + [BusinessAddress2] = @BusinessAddress2, + [BusinessAddress3] = @BusinessAddress3, + [BusinessCountry] = @BusinessCountry, + [BusinessTaxNumber] = @BusinessTaxNumber, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseTotp] = @UseTotp, + [SelfHost] = @SelfHost, + [UsersGetPremium] = @UsersGetPremium, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationUserOrganizationDetailsView') +BEGIN + DROP VIEW [dbo].[OrganizationUserOrganizationDetailsView] +END +GO + +CREATE VIEW [dbo].[OrganizationUserOrganizationDetailsView] +AS +SELECT + OU.[UserId], + OU.[OrganizationId], + O.[Name], + O.[Enabled], + O.[UseGroups], + O.[UseDirectory], + O.[UseTotp], + O.[SelfHost], + O.[UsersGetPremium], + O.[Seats], + O.[MaxCollections], + O.[MaxStorageGb], + OU.[Key], + OU.[Status], + OU.[Type] +FROM + [dbo].[OrganizationUser] OU +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationView') +BEGIN + DROP VIEW [dbo].[OrganizationView] +END +GO + +CREATE VIEW [dbo].[OrganizationView] +AS +SELECT + * +FROM + [dbo].[Organization] +GO diff --git a/src/Migrator/DbScripts/2017-11-13_00_IndexTuning.sql b/src/Migrator/DbScripts/2017-11-13_00_IndexTuning.sql new file mode 100644 index 000000000..ec968eff5 --- /dev/null +++ b/src/Migrator/DbScripts/2017-11-13_00_IndexTuning.sql @@ -0,0 +1,76 @@ +IF OBJECT_ID('[dbo].[OrganizationUser_ReadByOrganizationIdEmail]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadByOrganizationIdEmail] +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_ReadCountByOrganizationIdEmail]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationIdEmail] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_ReadCountByOrganizationIdEmail] + @OrganizationId UNIQUEIDENTIFIER, + @Email NVARCHAR(50), + @OnlyUsers BIT +AS +BEGIN + SET NOCOUNT ON + + SELECT + COUNT(1) + FROM + [dbo].[OrganizationUser] OU + LEFT JOIN + [dbo].[User] U ON OU.[UserId] = U.[Id] + WHERE + OU.[OrganizationId] = @OrganizationId + AND ( + (@OnlyUsers = 0 AND (OU.[Email] = @Email OR U.[Email] = @Email)) + OR (@OnlyUsers = 1 AND U.[Email] = @Email) + ) +END +GO + +IF EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_UserId_Type' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + DROP INDEX [IX_Cipher_UserId_Type] ON [dbo].[Cipher] +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_UserId_Type_IncludeAll' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Cipher_UserId_Type_IncludeAll] + ON [dbo].[Cipher]([UserId] ASC, [Type] ASC) + INCLUDE ([OrganizationId], [Data], [Favorites], [Folders], [Attachments], [CreationDate], [RevisionDate]) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name] = 'IX_Folder_UserId_IncludeAll' + AND object_id = OBJECT_ID('[dbo].[Folder]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Folder_UserId_IncludeAll] + ON [dbo].[Folder]([UserId] ASC) + INCLUDE ([Name], [CreationDate], [RevisionDate]) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name] = 'IX_OrganizationUser_UserIdOrganizationIdStatus' + AND object_id = OBJECT_ID('[dbo].[OrganizationUser]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_OrganizationUser_UserIdOrganizationIdStatus] + ON [dbo].[OrganizationUser]([UserId] ASC,[OrganizationId] ASC,[Status] ASC) + INCLUDE ([AccessAll]) +END +GO diff --git a/src/Migrator/DbScripts/2017-11-24_00_UpdateProcs.sql b/src/Migrator/DbScripts/2017-11-24_00_UpdateProcs.sql new file mode 100644 index 000000000..1ac38dbcb --- /dev/null +++ b/src/Migrator/DbScripts/2017-11-24_00_UpdateProcs.sql @@ -0,0 +1,1224 @@ +IF OBJECT_ID('[dbo].[User_BumpAccountRevisionDateByCipherId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_BumpAccountRevisionDateByCipherId] +END +GO + +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByCipherId] + @CipherId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + LEFT JOIN + [dbo].[CollectionCipher] CC ON CC.[CipherId] = @CipherId + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = CC.[CollectionId] + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = CC.[CollectionId] + WHERE + OU.[Status] = 2 -- 2 = Confirmed + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR ( + OU.[OrganizationId] = @OrganizationId + AND ( + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) + ) + ) +END +GO + +IF OBJECT_ID('[dbo].[User_BumpAccountRevisionDateByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_BumpAccountRevisionDateByCollectionId] +END +GO + +CREATE PROCEDURE [dbo].[User_BumpAccountRevisionDateByCollectionId] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + UPDATE + U + SET + U.[AccountRevisionDate] = GETUTCDATE() + FROM + [dbo].[User] U + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[UserId] = U.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId + WHERE + OU.[Status] = 2 -- 2 = Confirmed + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR ( + OU.[OrganizationId] = @OrganizationId + AND ( + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) + ) + ) +END +GO + +IF OBJECT_ID('[dbo].[Cipher_DeleteByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteByUserId] + @UserId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + + -- Delete ciphers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION Cipher_DeleteByUserId_Ciphers + + DELETE TOP(@BatchSize) + FROM + [dbo].[Cipher] + WHERE + [UserId] = @UserId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION Cipher_DeleteByUserId_Ciphers + END + + -- Delete folders + DELETE + FROM + [dbo].[Folder] + WHERE + [UserId] = @UserId + + -- Cleanup user + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO + +IF OBJECT_ID('[dbo].[User_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_DeleteById] +END +GO + +CREATE 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 organization users + DELETE + FROM + [dbo].[OrganizationUser] + WHERE + [UserId] = @Id + + -- Delete U2F logins + DELETE + FROM + [dbo].[U2f] + WHERE + [UserId] = @Id + + -- Finally, delete the user + DELETE + FROM + [dbo].[User] + WHERE + [Id] = @Id + + COMMIT TRANSACTION User_DeleteById +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_Create] +END +GO + +CREATE 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 + @OrganizationUseTotp BIT -- not used +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] + ) + 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 + ) + + 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 + +IF OBJECT_ID('[dbo].[CipherDetails_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_Update] +END +GO + +CREATE 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), -- not used + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @FolderId UNIQUEIDENTIFIER, + @Favorite BIT, + @Edit BIT, -- not used + @OrganizationUseTotp BIT -- not used +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, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + 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 + +IF OBJECT_ID('[dbo].[Cipher_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_Create] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_Create] + @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) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Cipher] + ( + [Id], + [UserId], + [OrganizationId], + [Type], + [Data], + [Favorites], + [Folders], + [Attachments], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @UserId, + @OrganizationId, + @Type, + @Data, + @Favorites, + @Folders, + @Attachments, + @CreationDate, + @RevisionDate + ) + + 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 + +IF OBJECT_ID('[dbo].[Cipher_DeleteAttachment]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteAttachment] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteAttachment] + @Id UNIQUEIDENTIFIER, + @AttachmentId VARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + DECLARE @AttachmentIdKey VARCHAR(50) = CONCAT('"', @AttachmentId, '"') + DECLARE @AttachmentIdPath VARCHAR(50) = CONCAT('$.', @AttachmentIdKey) + + DECLARE @UserId UNIQUEIDENTIFIER + DECLARE @OrganizationId UNIQUEIDENTIFIER + + SELECT + @UserId = [UserId], + @OrganizationId = [OrganizationId] + FROM + [dbo].[Cipher] + WHERE [Id] = @Id + + UPDATE + [dbo].[Cipher] + SET + [Attachments] = JSON_MODIFY([Attachments], @AttachmentIdPath, NULL) + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO + +IF OBJECT_ID('[dbo].[Cipher_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteById] + @Id UNIQUEIDENTIFIER +WITH RECOMPILE +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER + DECLARE @OrganizationId UNIQUEIDENTIFIER + DECLARE @Attachments BIT + + SELECT TOP 1 + @UserId = [UserId], + @OrganizationId = [OrganizationId], + @Attachments = CASE WHEN [Attachments] IS NOT NULL THEN 1 ELSE 0 END + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + DELETE + FROM + [dbo].[Cipher] + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + END + EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + IF @Attachments = 1 + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + END + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO + +IF OBJECT_ID('[dbo].[Cipher_Move]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_Move] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_Move] + @Ids AS [dbo].[GuidIdArray] READONLY, + @FolderId AS UNIQUEIDENTIFIER, + @UserId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserIdKey VARCHAR(50) = CONCAT('"', @UserId, '"') + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$.', @UserIdKey) + + ;WITH [IdsToMoveCTE] AS ( + SELECT + [Id] + FROM + [dbo].[UserCipherDetails](@UserId) + WHERE + [Edit] = 1 + AND [Id] IN (SELECT * FROM @Ids) + ) + UPDATE + [dbo].[Cipher] + SET + [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 + WHERE + [Id] IN (SELECT * FROM [IdsToMoveCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO + +IF OBJECT_ID('[dbo].[Cipher_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_Update] +END +GO + +CREATE 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) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Cipher] + SET + [UserId] = @UserId, + [OrganizationId] = @OrganizationId, + [Type] = @Type, + [Data] = @Data, + [Favorites] = @Favorites, + [Folders] = @Folders, + [Attachments] = @Attachments, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + 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 + +IF OBJECT_ID('[dbo].[Cipher_UpdateAttachment]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateAttachment] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_UpdateAttachment] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @AttachmentId VARCHAR(50), + @AttachmentData NVARCHAR(MAX) +AS +BEGIN + SET NOCOUNT ON + + DECLARE @AttachmentIdKey VARCHAR(50) = CONCAT('"', @AttachmentId, '"') + DECLARE @AttachmentIdPath VARCHAR(50) = CONCAT('$.', @AttachmentIdKey) + + UPDATE + [dbo].[Cipher] + SET + [Attachments] = + CASE + WHEN [Attachments] IS NULL THEN + CONCAT('{', @AttachmentIdKey, ':', @AttachmentData, '}') + ELSE + JSON_MODIFY([Attachments], @AttachmentIdPath, JSON_QUERY(@AttachmentData, '$')) + END + WHERE + [Id] = @Id + + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByCipherId] @Id, @OrganizationId + END + ELSE IF @UserId IS NOT NULL + BEGIN + EXEC [dbo].[User_UpdateStorage] @UserId + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId + END +END +GO + +IF OBJECT_ID('[dbo].[Cipher_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateWithCollections] +END +GO + +CREATE 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), + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + SELECT -1 -- -1 = Failure + RETURN + END + + UPDATE + [dbo].[Cipher] + SET + [UserId] = NULL, + [OrganizationId] = @OrganizationId, + [Data] = @Data, + [Attachments] = @Attachments, + [RevisionDate] = @RevisionDate + -- No need to update CreationDate, Favorites, Folders, or Type since that data will not change + WHERE + [Id] = @Id + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Id], + @Id + FROM + @CollectionIds + WHERE + [Id] IN (SELECT [Id] FROM #AvailableCollections) + + 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 + +IF OBJECT_ID('[dbo].[CollectionCipher_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_Create] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_Create] + @CollectionId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + VALUES + ( + @CollectionId, + @CipherId + ) + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Cipher] WHERE [Id] = @CipherId) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrganizationId + END +END +GO + +IF OBJECT_ID('[dbo].[CollectionCipher_Delete]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_Delete] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_Delete] + @CollectionId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[CollectionCipher] + WHERE + [CollectionId] = @CollectionId + AND [CipherId] = @CipherId + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Cipher] WHERE [Id] = @CipherId) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrganizationId + END +END +GO + +IF OBJECT_ID('[dbo].[Collection_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_Create] +END +GO + +CREATE PROCEDURE [dbo].[Collection_Create] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Collection] + ( + [Id], + [OrganizationId], + [Name], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @OrganizationId, + @Name, + @CreationDate, + @RevisionDate + ) + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_CreateWithGroups]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_CreateWithGroups] +END +GO + +CREATE PROCEDURE [dbo].[Collection_CreateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Create] @Id, @OrganizationId, @Name, @CreationDate, @RevisionDate + + ;WITH [AvailableGroupsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Group] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly] + ) + SELECT + @Id, + [Id], + [ReadOnly] + FROM + @Groups + WHERE + [Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Collection_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Collection] WHERE [Id] = @Id) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId + END + + DELETE + FROM + [dbo].[CollectionGroup] + WHERE + [CollectionId] = @Id + + DELETE + FROM + [dbo].[Collection] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Collection_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_Update] +END +GO + +CREATE PROCEDURE [dbo].[Collection_Update] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Collection] + SET + [OrganizationId] = @OrganizationId, + [Name] = @Name, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_UpdateWithGroups]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_UpdateWithGroups] +END +GO + +CREATE PROCEDURE [dbo].[Collection_UpdateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @CreationDate, @RevisionDate + + ;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 VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[GroupUser_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[GroupUser_UpdateUsers] +END +GO + +CREATE PROCEDURE [dbo].[GroupUser_UpdateUsers] + @GroupId UNIQUEIDENTIFIER, + @OrganizationUserIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Group] + WHERE + [Id] = @GroupId + ) + + ;WITH [AvailableUsersCTE] AS( + SELECT + [Id] + FROM + [dbo].[OrganizationUser] + WHERE + [OrganizationId] = @OrgId + ) + MERGE + [dbo].[GroupUser] AS [Target] + USING + @OrganizationUserIds AS [Source] + ON + [Target].[GroupId] = @GroupId + AND [Target].[OrganizationUserId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN + INSERT VALUES + ( + @GroupId, + [Source].[Id] + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @GroupId + AND [Target].[OrganizationUserId] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId +END +GO + +IF OBJECT_ID('[dbo].[Group_CreateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Group_CreateWithCollections] +END +GO + +CREATE PROCEDURE [dbo].[Group_CreateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] 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] + ) + SELECT + [Id], + @Id, + [ReadOnly] + FROM + @Collections + WHERE + [Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Group_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Group_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Group_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrganizationId UNIQUEIDENTIFIER = (SELECT TOP 1 [OrganizationId] FROM [dbo].[Group] WHERE [Id] = @Id) + IF @OrganizationId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId + END + + DELETE + FROM + [dbo].[Group] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Group_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Group_UpdateWithCollections] +END +GO + +CREATE PROCEDURE [dbo].[Group_UpdateWithCollections] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @AccessAll BIT, + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Collections AS [dbo].[SelectionReadOnlyArray] 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 VALUES + ( + [Source].[Id], + @Id, + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[GroupId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUser_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUser_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUser_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationUserId] @Id + + DELETE + FROM + [dbo].[CollectionUser] + WHERE + [OrganizationUserId] = @Id + + DELETE + FROM + [dbo].[GroupUser] + WHERE + [OrganizationUserId] = @Id + + DELETE + FROM + [dbo].[OrganizationUser] + WHERE + [Id] = @Id +END +GO diff --git a/src/Migrator/DbScripts/2017-12-12_00_Events.sql b/src/Migrator/DbScripts/2017-12-12_00_Events.sql new file mode 100644 index 000000000..e92dda9c9 --- /dev/null +++ b/src/Migrator/DbScripts/2017-12-12_00_Events.sql @@ -0,0 +1,498 @@ +IF COL_LENGTH('[dbo].[Organization]', 'UseEvents') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [UseEvents] BIT NULL +END +GO + +UPDATE + [dbo].[Organization] +SET + [UseEvents] = (CASE WHEN [PlanType] = 5 OR [PlanType] = 4 THEN 1 ELSE 0 END) +GO + +ALTER TABLE + [dbo].[Organization] +ALTER COLUMN + [UseEvents] BIT NOT NULL +GO + +IF OBJECT_ID('[dbo].[Organization_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Create] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BusinessAddress1], + [BusinessAddress2], + [BusinessAddress3], + [BusinessCountry], + [BusinessTaxNumber], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseEvents], + [UseTotp], + [SelfHost], + [UsersGetPremium], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BusinessAddress1, + @BusinessAddress2, + @BusinessAddress3, + @BusinessCountry, + @BusinessTaxNumber, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseEvents, + @UseTotp, + @SelfHost, + @UsersGetPremium, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Update] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BusinessAddress1] = @BusinessAddress1, + [BusinessAddress2] = @BusinessAddress2, + [BusinessAddress3] = @BusinessAddress3, + [BusinessCountry] = @BusinessCountry, + [BusinessTaxNumber] = @BusinessTaxNumber, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseEvents] = @UseEvents, + [UseTotp] = @UseTotp, + [SelfHost] = @SelfHost, + [UsersGetPremium] = @UsersGetPremium, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Organization_ReadAbilities]') IS NULL +BEGIN + EXEC('CREATE PROCEDURE [dbo].[Organization_ReadAbilities] AS BEGIN SET NOCOUNT ON; END') +END +GO + +ALTER PROCEDURE [dbo].[Organization_ReadAbilities] +AS +BEGIN + SET NOCOUNT ON + + SELECT + [Id], + [UseEvents], + [Enabled] + FROM + [dbo].[Organization] +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationView') +BEGIN + DROP VIEW [dbo].[OrganizationView] +END +GO + +CREATE VIEW [dbo].[OrganizationView] +AS +SELECT + * +FROM + [dbo].[Organization] +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationUserOrganizationDetailsView') +BEGIN + DROP VIEW [dbo].[OrganizationUserOrganizationDetailsView] +END +GO + +CREATE VIEW [dbo].[OrganizationUserOrganizationDetailsView] +AS +SELECT + OU.[UserId], + OU.[OrganizationId], + O.[Name], + O.[Enabled], + O.[UseGroups], + O.[UseDirectory], + O.[UseEvents], + O.[UseTotp], + O.[SelfHost], + O.[UsersGetPremium], + O.[Seats], + O.[MaxCollections], + O.[MaxStorageGb], + OU.[Key], + OU.[Status], + OU.[Type] +FROM + [dbo].[OrganizationUser] OU +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] +GO + +IF OBJECT_ID('[dbo].[Event]') IS NULL +BEGIN + CREATE TABLE [dbo].[Event] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Type] INT NOT NULL, + [UserId] UNIQUEIDENTIFIER NULL, + [OrganizationId] UNIQUEIDENTIFIER NULL, + [CipherId] UNIQUEIDENTIFIER NULL, + [CollectionId] UNIQUEIDENTIFIER NULL, + [GroupId] UNIQUEIDENTIFIER NULL, + [OrganizationUserId] UNIQUEIDENTIFIER NULL, + [ActingUserId] UNIQUEIDENTIFIER NULL, + [DeviceType] SMALLINT NULL, + [IpAddress] VARCHAR(50) NULL, + [Date] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Event] PRIMARY KEY CLUSTERED ([Id] ASC) + ); + + CREATE NONCLUSTERED INDEX [IX_Event_DateOrganizationIdUserId] + ON [dbo].[Event]([Date] DESC, [OrganizationId] ASC, [ActingUserId] ASC, [CipherId] ASC); +END +GO + +IF OBJECT_ID('[dbo].[Event_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Event_Create] +END +GO + +CREATE PROCEDURE [dbo].[Event_Create] + @Id UNIQUEIDENTIFIER, + @Type INT, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER, + @CollectionId UNIQUEIDENTIFIER, + @GroupId UNIQUEIDENTIFIER, + @OrganizationUserId UNIQUEIDENTIFIER, + @ActingUserId UNIQUEIDENTIFIER, + @DeviceType SMALLINT, + @IpAddress VARCHAR(50), + @Date DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Event] + ( + [Id], + [Type], + [UserId], + [OrganizationId], + [CipherId], + [CollectionId], + [GroupId], + [OrganizationUserId], + [ActingUserId], + [DeviceType], + [IpAddress], + [Date] + ) + VALUES + ( + @Id, + @Type, + @UserId, + @OrganizationId, + @CipherId, + @CollectionId, + @GroupId, + @OrganizationUserId, + @ActingUserId, + @DeviceType, + @IpAddress, + @Date + ) +END +GO + +IF OBJECT_ID('[dbo].[Event_ReadPageByCipherId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Event_ReadPageByCipherId] +END +GO + +CREATE PROCEDURE [dbo].[Event_ReadPageByCipherId] + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CipherId UNIQUEIDENTIFIER, + @StartDate DATETIME2(7), + @EndDate DATETIME2(7), + @BeforeDate DATETIME2(7), + @PageSize INT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[EventView] + WHERE + [Date] >= @StartDate + AND (@BeforeDate IS NOT NULL OR [Date] <= @EndDate) + AND (@BeforeDate IS NULL OR [Date] < @BeforeDate) + AND ( + (@OrganizationId IS NULL AND [OrganizationId] IS NULL) + OR (@OrganizationId IS NOT NULL AND [OrganizationId] = @OrganizationId) + ) + AND ( + (@UserId IS NULL AND [UserId] IS NULL) + OR (@UserId IS NOT NULL AND [UserId] = @UserId) + ) + AND [CipherId] = @CipherId + ORDER BY [Date] DESC + OFFSET 0 ROWS + FETCH NEXT @PageSize ROWS ONLY +END +GO + +IF OBJECT_ID('[dbo].[Event_ReadPageByOrganizationId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Event_ReadPageByOrganizationId] +END +GO + +CREATE PROCEDURE [dbo].[Event_ReadPageByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER, + @StartDate DATETIME2(7), + @EndDate DATETIME2(7), + @BeforeDate DATETIME2(7), + @PageSize INT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[EventView] + WHERE + [Date] >= @StartDate + AND (@BeforeDate IS NOT NULL OR [Date] <= @EndDate) + AND (@BeforeDate IS NULL OR [Date] < @BeforeDate) + AND [OrganizationId] = @OrganizationId + ORDER BY [Date] DESC + OFFSET 0 ROWS + FETCH NEXT @PageSize ROWS ONLY +END +GO + +IF OBJECT_ID('[dbo].[Event_ReadPageByOrganizationIdActingUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Event_ReadPageByOrganizationIdActingUserId] +END +GO + +CREATE PROCEDURE [dbo].[Event_ReadPageByOrganizationIdActingUserId] + @OrganizationId UNIQUEIDENTIFIER, + @ActingUserId UNIQUEIDENTIFIER, + @StartDate DATETIME2(7), + @EndDate DATETIME2(7), + @BeforeDate DATETIME2(7), + @PageSize INT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[EventView] + WHERE + [Date] >= @StartDate + AND (@BeforeDate IS NOT NULL OR [Date] <= @EndDate) + AND (@BeforeDate IS NULL OR [Date] < @BeforeDate) + AND [OrganizationId] = @OrganizationId + AND [ActingUserId] = @ActingUserId + ORDER BY [Date] DESC + OFFSET 0 ROWS + FETCH NEXT @PageSize ROWS ONLY +END +GO + +IF OBJECT_ID('[dbo].[Event_ReadPageByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Event_ReadPageByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Event_ReadPageByUserId] + @UserId UNIQUEIDENTIFIER, + @StartDate DATETIME2(7), + @EndDate DATETIME2(7), + @BeforeDate DATETIME2(7), + @PageSize INT +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[EventView] + WHERE + [Date] >= @StartDate + AND (@BeforeDate IS NOT NULL OR [Date] <= @EndDate) + AND (@BeforeDate IS NULL OR [Date] < @BeforeDate) + AND [OrganizationId] IS NULL + AND [ActingUserId] = @UserId + ORDER BY [Date] DESC + OFFSET 0 ROWS + FETCH NEXT @PageSize ROWS ONLY +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'EventView') +BEGIN + DROP VIEW [dbo].[EventView] +END +GO + +CREATE VIEW [dbo].[EventView] +AS +SELECT + * +FROM + [dbo].[Event] +GO diff --git a/src/Migrator/DbScripts/2018-02-28_00_LoginUris.sql b/src/Migrator/DbScripts/2018-02-28_00_LoginUris.sql new file mode 100644 index 000000000..6e03d5c9f --- /dev/null +++ b/src/Migrator/DbScripts/2018-02-28_00_LoginUris.sql @@ -0,0 +1,112 @@ +/* +{ + "Name":"2.xx", + "Uri":"2.yy", + "Username":"2.zz", + "Password":"2.aa" +} +=> +{ + "Name":"2.xx", + "Username":"2.zz", + "Password":"2.aa", + "Uris":[{"Uri": "2.yy"}] +} +*/ + +IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'CompletedIds') +BEGIN + CREATE TABLE [CompletedIds] ([Id] UNIQUEIDENTIFIER PRIMARY KEY) +END +GO + +DECLARE @UriPath VARCHAR(50) = '$.Uri' +DECLARE @UrisPath VARCHAR(50) = '$.Uris' +DECLARE @BatchSize INT = 1000 +DECLARE @LastId UNIQUEIDENTIFIER = NULL + +-- Step 1: Add new Uris property with data from Uri +WHILE @BatchSize > 0 +BEGIN + SELECT TOP 1 + @LastId = [Id] + FROM + [CompletedIds] + ORDER BY + [Id] DESC + + ;WITH [CTE] AS ( + SELECT TOP (@BatchSize) + * + FROM + [Cipher] + WHERE + (@LastId IS NULL OR [Id] > @LastId) + AND JSON_VALUE([Data], @UriPath) IS NOT NULL + AND JSON_QUERY([Data], @UrisPath) IS NULL + ORDER BY + [Id] ASC + ) + UPDATE + [CTE] + SET + [Data] = JSON_MODIFY( + [Data], + @UrisPath, + JSON_QUERY( + '[{"Uri":"' + CAST(JSON_VALUE([Data], @UriPath) AS NVARCHAR(MAX)) + '"}]', + '$' + ) + ) + OUTPUT INSERTED.[Id] INTO [CompletedIds] + + SET @BatchSize = @@ROWCOUNT + RAISERROR('Updated %d ciphers with Uris', 0, 1, @BatchSize) WITH NOWAIT +END +GO + +-- Reset +TRUNCATE TABLE [CompletedIds] +DECLARE @UriPath VARCHAR(50) = '$.Uri' +DECLARE @UrisPath VARCHAR(50) = '$.Uris' +DECLARE @BatchSize INT = 1000 +DECLARE @LastId UNIQUEIDENTIFIER = NULL + +-- Step 2: Remove old Uri Property +WHILE @BatchSize > 0 +BEGIN + SELECT TOP 1 + @LastId = [Id] + FROM + [CompletedIds] + ORDER BY + [Id] DESC + + ;WITH [CTE] AS ( + SELECT TOP (@BatchSize) + * + FROM + [Cipher] + WHERE + (@LastId IS NULL OR [Id] > @LastId) + AND JSON_VALUE([Data], @UriPath) IS NOT NULL + AND JSON_QUERY([Data], @UrisPath) IS NOT NULL + ORDER BY + [Id] ASC + ) + UPDATE + [CTE] + SET + [Data] = JSON_MODIFY([Data], @UriPath, NULL) + OUTPUT INSERTED.[Id] INTO [CompletedIds] + + SET @BatchSize = @@ROWCOUNT + RAISERROR('Updated %d ciphers with Uri removal', 0, 1, @BatchSize) WITH NOWAIT +END +GO + +IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'CompletedIds') +BEGIN + DROP TABLE [CompletedIds] +END +GO diff --git a/src/Migrator/DbScripts/2018-03-12_00_FixLoginUris.sql b/src/Migrator/DbScripts/2018-03-12_00_FixLoginUris.sql new file mode 100644 index 000000000..d45592dc2 --- /dev/null +++ b/src/Migrator/DbScripts/2018-03-12_00_FixLoginUris.sql @@ -0,0 +1,69 @@ +/* +{ + "Name":"2.xx", + "Username":"2.zz", + "Password":"2.aa", + "Uris":"[{\"Uri\":\"2.yy\"}]" +} +=> +{ + "Name":"2.xx", + "Username":"2.zz", + "Password":"2.aa", + "Uris":[{"Uri": "2.yy"}] +} +*/ + +IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'CompletedIds') +BEGIN + CREATE TABLE [CompletedIds] ([Id] UNIQUEIDENTIFIER PRIMARY KEY) +END +GO + +DECLARE @UrisPath VARCHAR(50) = '$.Uris' +DECLARE @BatchSize INT = 1000 +DECLARE @LastId UNIQUEIDENTIFIER = NULL + +WHILE @BatchSize > 0 +BEGIN + SELECT TOP 1 + @LastId = [Id] + FROM + [CompletedIds] + ORDER BY + [Id] DESC + + ;WITH [CTE] AS ( + SELECT TOP (@BatchSize) + * + FROM + [Cipher] + WHERE + (@LastId IS NULL OR [Id] > @LastId) + AND LEFT(JSON_VALUE([Data], @UrisPath), 8) = '[{"Uri":' + ORDER BY + [Id] ASC + ) + UPDATE + [CTE] + SET + [Data] = JSON_MODIFY( + [Data], + @UrisPath, + JSON_QUERY( + JSON_VALUE([Data], @UrisPath), + '$' + ) + ) + OUTPUT INSERTED.[Id] INTO [CompletedIds] + + SET @BatchSize = @@ROWCOUNT + RAISERROR('Updated %d ciphers with Uris', 0, 1, @BatchSize) WITH NOWAIT +END +GO + +IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'CompletedIds') +BEGIN + DROP TABLE [CompletedIds] +END +GO diff --git a/src/Migrator/DbScripts/2018-03-21_00_AdminPortal.sql b/src/Migrator/DbScripts/2018-03-21_00_AdminPortal.sql new file mode 100644 index 000000000..f2439b986 --- /dev/null +++ b/src/Migrator/DbScripts/2018-03-21_00_AdminPortal.sql @@ -0,0 +1,232 @@ +IF OBJECT_ID('[dbo].[User_Search]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_Search] +END +GO + +CREATE PROCEDURE [dbo].[User_Search] + @Email NVARCHAR(50), + @Skip INT = 0, + @Take INT = 25 +WITH RECOMPILE +AS +BEGIN + SET NOCOUNT ON + DECLARE @EmailLikeSearch NVARCHAR(55) = @Email + '%' + + SELECT + * + FROM + [dbo].[UserView] + WHERE + (@Email IS NULL OR [Email] LIKE @EmailLikeSearch) + ORDER BY [Email] ASC + OFFSET @Skip ROWS + FETCH NEXT @Take ROWS ONLY +END +GO + +IF OBJECT_ID('[dbo].[Organization_Search]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Search] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Search] + @Name NVARCHAR(50), + @UserEmail NVARCHAR(50), + @Paid BIT, + @Skip INT = 0, + @Take INT = 25 +WITH RECOMPILE +AS +BEGIN + SET NOCOUNT ON + DECLARE @NameLikeSearch NVARCHAR(55) = '%' + @Name + '%' + + IF @UserEmail IS NOT NULL + BEGIN + SELECT + O.* + FROM + [dbo].[OrganizationView] O + INNER JOIN + [dbo].[OrganizationUser] OU ON O.[Id] = OU.[OrganizationId] + INNER JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] + WHERE + (@Name IS NULL OR O.[Name] LIKE @NameLikeSearch) + AND (@UserEmail IS NULL OR U.[Email] = @UserEmail) + AND + ( + @Paid IS NULL OR + ( + (@Paid = 1 AND O.[GatewaySubscriptionId] IS NOT NULL) OR + (@Paid = 0 AND O.[GatewaySubscriptionId] IS NULL) + ) + ) + ORDER BY O.[CreationDate] DESC + OFFSET @Skip ROWS + FETCH NEXT @Take ROWS ONLY + END + ELSE + BEGIN + SELECT + O.* + FROM + [dbo].[OrganizationView] O + WHERE + (@Name IS NULL OR O.[Name] LIKE @NameLikeSearch) + AND + ( + @Paid IS NULL OR + ( + (@Paid = 1 AND O.[GatewaySubscriptionId] IS NOT NULL) OR + (@Paid = 0 AND O.[GatewaySubscriptionId] IS NULL) + ) + ) + ORDER BY O.[CreationDate] DESC + OFFSET @Skip ROWS + FETCH NEXT @Take ROWS ONLY + END +END +GO + +IF OBJECT_ID('[dbo].[Folder_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Folder_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Folder_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER = (SELECT TOP 1 [UserId] FROM [dbo].[Folder] WHERE [Id] = @Id) + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$."', @UserId, '"') + + UPDATE + C + SET + C.[Folders] = JSON_MODIFY(C.[Folders], @UserIdPath, NULL) + FROM + [dbo].[Cipher] C + LEFT JOIN + [dbo].[Organization] O ON C.[UserId] IS NULL AND O.[Id] = C.[OrganizationId] + LEFT JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + LEFT JOIN + [dbo].[CollectionCipher] CC ON C.[UserId] IS NULL AND OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] AND CU.[OrganizationUserId] = OU.[Id] + WHERE + ( + C.[UserId] = @UserId + OR ( + C.[UserId] IS NULL + AND (OU.[AccessAll] = 1 OR CU.[CollectionId] IS NOT NULL) + ) + ) + AND JSON_VALUE(C.[Folders], @UserIdPath) = @Id + + DELETE + FROM + [dbo].[Folder] + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO + +IF OBJECT_ID('[dbo].[Organization_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[Organization_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + [dbo].[Cipher] + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [dbo].[Cipher] C + LEFT JOIN + [CTE] ON C.[Id] = [CTE].[Id] + WHERE + C.[OrganizationId] = @Id + + UPDATE + [dbo].[Organization] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[User_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + [dbo].[Cipher] + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [dbo].[Cipher] C + LEFT JOIN + [CTE] ON C.[Id] = [CTE].[Id] + WHERE + C.[UserId] = @Id + + UPDATE + [dbo].[User] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO diff --git a/src/Migrator/DbScripts/2018-04-02_00_Org2fa.sql b/src/Migrator/DbScripts/2018-04-02_00_Org2fa.sql new file mode 100644 index 000000000..7b9ac7e5e --- /dev/null +++ b/src/Migrator/DbScripts/2018-04-02_00_Org2fa.sql @@ -0,0 +1,295 @@ +IF COL_LENGTH('[dbo].[Organization]', 'Use2fa') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [Use2fa] BIT NULL +END +GO + +UPDATE + [dbo].[Organization] +SET + [Use2fa] = (CASE WHEN [PlanType] = 5 OR [PlanType] = 4 THEN 1 ELSE 0 END) +GO + +ALTER TABLE + [dbo].[Organization] +ALTER COLUMN + [Use2fa] BIT NOT NULL +GO + +IF COL_LENGTH('[dbo].[Organization]', 'TwoFactorProviders') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [TwoFactorProviders] NVARCHAR(MAX) NULL +END +GO + +IF OBJECT_ID('[dbo].[Organization_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Create] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @Use2fa BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @TwoFactorProviders NVARCHAR(MAX), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BusinessAddress1], + [BusinessAddress2], + [BusinessAddress3], + [BusinessCountry], + [BusinessTaxNumber], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseEvents], + [UseTotp], + [Use2fa], + [SelfHost], + [UsersGetPremium], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [TwoFactorProviders], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BusinessAddress1, + @BusinessAddress2, + @BusinessAddress3, + @BusinessCountry, + @BusinessTaxNumber, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseEvents, + @UseTotp, + @Use2fa, + @SelfHost, + @UsersGetPremium, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @TwoFactorProviders, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Update] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @Use2fa BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @TwoFactorProviders NVARCHAR(MAX), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BusinessAddress1] = @BusinessAddress1, + [BusinessAddress2] = @BusinessAddress2, + [BusinessAddress3] = @BusinessAddress3, + [BusinessCountry] = @BusinessCountry, + [BusinessTaxNumber] = @BusinessTaxNumber, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseEvents] = @UseEvents, + [UseTotp] = @UseTotp, + [Use2fa] = @Use2fa, + [SelfHost] = @SelfHost, + [UsersGetPremium] = @UsersGetPremium, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [TwoFactorProviders] = @TwoFactorProviders, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Organization_ReadAbilities]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_ReadAbilities] +END +GO + +CREATE PROCEDURE [dbo].[Organization_ReadAbilities] +AS +BEGIN + SET NOCOUNT ON + + SELECT + [Id], + [UseEvents], + [Use2fa], + CASE + WHEN [Use2fa] = 1 AND [TwoFactorProviders] IS NOT NULL AND [TwoFactorProviders] != '{}' THEN + 1 + ELSE + 0 + END AS [Using2fa], + [Enabled] + FROM + [dbo].[Organization] +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationView') +BEGIN + DROP VIEW [dbo].[OrganizationView] +END +GO + +CREATE VIEW [dbo].[OrganizationView] +AS +SELECT + * +FROM + [dbo].[Organization] +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationUserOrganizationDetailsView') +BEGIN + DROP VIEW [dbo].[OrganizationUserOrganizationDetailsView] +END +GO + +CREATE VIEW [dbo].[OrganizationUserOrganizationDetailsView] +AS +SELECT + OU.[UserId], + OU.[OrganizationId], + O.[Name], + O.[Enabled], + O.[UseGroups], + O.[UseDirectory], + O.[UseEvents], + O.[UseTotp], + O.[Use2fa], + O.[SelfHost], + O.[UsersGetPremium], + O.[Seats], + O.[MaxCollections], + O.[MaxStorageGb], + OU.[Key], + OU.[Status], + OU.[Type] +FROM + [dbo].[OrganizationUser] OU +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] +GO diff --git a/src/Migrator/DbScripts/2018-04-24_00_CipherQueryTuning.sql b/src/Migrator/DbScripts/2018-04-24_00_CipherQueryTuning.sql new file mode 100644 index 000000000..d37fa258e --- /dev/null +++ b/src/Migrator/DbScripts/2018-04-24_00_CipherQueryTuning.sql @@ -0,0 +1,319 @@ +IF OBJECT_ID('[dbo].[CipherDetails]') IS NOT NULL +BEGIN + DROP FUNCTION [dbo].[CipherDetails] +END +GO + +CREATE 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] +FROM + [dbo].[Cipher] C +GO + +IF OBJECT_ID('[dbo].[UserCipherDetails]') IS NOT NULL +BEGIN + DROP FUNCTION [dbo].[UserCipherDetails] +END +GO + +CREATE FUNCTION [dbo].[UserCipherDetails](@UserId UNIQUEIDENTIFIER) +RETURNS TABLE +AS RETURN +WITH [CTE] AS ( + SELECT + [Id], + [OrganizationId], + [AccessAll] + FROM + [OrganizationUser] + WHERE + [UserId] = @UserId + AND [Status] = 2 -- Confirmed +) +SELECT + C.*, + CASE + WHEN + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + THEN 1 + ELSE 0 + END [Edit], + CASE + WHEN O.[UseTotp] = 1 + THEN 1 + ELSE 0 + END [OrganizationUseTotp] +FROM + [dbo].[CipherDetails](@UserId) C +INNER JOIN + [CTE] OU ON C.[UserId] IS NULL AND C.[OrganizationId] IN (SELECT [OrganizationId] FROM [CTE]) +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.OrganizationId AND O.[Id] = C.[OrganizationId] AND O.[Enabled] = 1 +LEFT JOIN + [dbo].[CollectionCipher] CC ON OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] +LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] +WHERE + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL + +UNION ALL + +SELECT + *, + 1 [Edit], + 0 [OrganizationUseTotp] +FROM + [dbo].[CipherDetails](@UserId) +WHERE + [UserId] = @UserId +GO + +IF EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_OrganizationId_Type' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + DROP INDEX [IX_Cipher_OrganizationId_Type] ON [dbo].[Cipher] +END +GO + +IF EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_UserId_Type_IncludeAll' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + DROP INDEX [IX_Cipher_UserId_Type_IncludeAll] ON [dbo].[Cipher] +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_UserId_OrganizationId_IncludeAll' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Cipher_UserId_OrganizationId_IncludeAll] + ON [dbo].[Cipher]([UserId] ASC, [OrganizationId] ASC) + INCLUDE ([Type], [Data], [Favorites], [Folders], [Attachments], [CreationDate], [RevisionDate]) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Cipher_OrganizationId' + AND object_id = OBJECT_ID('[dbo].[Cipher]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Cipher_OrganizationId] + ON [dbo].[Cipher]([OrganizationId] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_GroupUser_OrganizationUserId' + AND object_id = OBJECT_ID('[dbo].[GroupUser]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_GroupUser_OrganizationUserId] + ON [dbo].[GroupUser]([OrganizationUserId] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Organization_Enabled' + AND object_id = OBJECT_ID('[dbo].[Organization]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Organization_Enabled] + ON [dbo].[Organization]([Id] ASC, [Enabled] ASC) + INCLUDE ([UseTotp]) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Collection_OrganizationId_IncludeAll' + AND object_id = OBJECT_ID('[dbo].[Collection]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Collection_OrganizationId_IncludeAll] + ON [dbo].[Collection]([OrganizationId] ASC) + INCLUDE([CreationDate], [Name], [RevisionDate]) +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_ReadByTypeUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_ReadByTypeUserId] +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_ReadByUserIdHasCollection]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_ReadByUserIdHasCollection] +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_ReadWithoutOrganizationsByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_ReadWithoutOrganizationsByUserId] +END +GO + +CREATE PROCEDURE [dbo].[CipherDetails_ReadWithoutOrganizationsByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + *, + 1 [Edit], + 0 [OrganizationUseTotp] + FROM + [dbo].[CipherDetails](@UserId) + WHERE + [UserId] = @UserId +END +GO + +IF OBJECT_ID('[dbo].[Cipher_ReadByOrganizationId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_ReadByOrganizationId] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[CipherView] + WHERE + [UserId] IS NULL + AND [OrganizationId] = @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Organization_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_DeleteById] +END +GO + +CREATE 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 + + DELETE + FROM + [dbo].[Organization] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Organization_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[Organization_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + [dbo].[Cipher] + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [dbo].[Cipher] C + LEFT JOIN + [CTE] ON C.[Id] = [CTE].[Id] + WHERE + C.[UserId] IS NULL + AND C.[OrganizationId] = @Id + + UPDATE + [dbo].[Organization] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO diff --git a/src/Migrator/DbScripts/2018-06-11_00_WebVaultUpdates.sql b/src/Migrator/DbScripts/2018-06-11_00_WebVaultUpdates.sql new file mode 100644 index 000000000..974f0a9e7 --- /dev/null +++ b/src/Migrator/DbScripts/2018-06-11_00_WebVaultUpdates.sql @@ -0,0 +1,719 @@ +IF COL_LENGTH('[dbo].[User]', 'RenewalReminderDate') IS NULL +BEGIN + ALTER TABLE + [dbo].[User] + ADD + [RenewalReminderDate] DATETIME2 (7) NULL +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_User_Premium_PremiumExpirationDate_RenewalReminderDate' + AND object_id = OBJECT_ID('[dbo].[User]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_User_Premium_PremiumExpirationDate_RenewalReminderDate] + ON [dbo].[User]([Premium] ASC, [PremiumExpirationDate] ASC, [RenewalReminderDate] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Grant_ExpirationDate' + AND object_id = OBJECT_ID('[dbo].[Grant]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Grant_ExpirationDate] + ON [dbo].[Grant]([ExpirationDate] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_U2f_CreationDate' + AND object_id = OBJECT_ID('[dbo].[U2f]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_U2f_CreationDate] + ON [dbo].[U2f]([CreationDate] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_U2f_UserId' + AND object_id = OBJECT_ID('[dbo].[U2f]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_U2f_UserId] + ON [dbo].[U2f]([UserId] ASC) +END +GO + +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_Device_Identifier' + AND object_id = OBJECT_ID('[dbo].[Device]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_Device_Identifier] + ON [dbo].[Device]([Identifier] ASC) +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'UserView') +BEGIN + DROP VIEW [dbo].[UserView] +END +GO + +CREATE VIEW [dbo].[UserView] +AS +SELECT + * +FROM + [dbo].[User] +GO + +IF OBJECT_ID('[dbo].[U2f_DeleteOld]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[U2f_DeleteOld] +END +GO + +CREATE PROCEDURE [dbo].[U2f_DeleteOld] +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + DECLARE @Threshold DATETIME2(7) = DATEADD (day, -7, GETUTCDATE()) + + WHILE @BatchSize > 0 + BEGIN + DELETE TOP(@BatchSize) + FROM + [dbo].[U2f] + WHERE + [CreationDate] IS NULL + OR [CreationDate] < @Threshold + + SET @BatchSize = @@ROWCOUNT + END +END +GO + +IF OBJECT_ID('[dbo].[Grant_DeleteExpired]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Grant_DeleteExpired] +END +GO + +CREATE PROCEDURE [dbo].[Grant_DeleteExpired] +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + DECLARE @Now DATETIME2(7) = GETUTCDATE() + + WHILE @BatchSize > 0 + BEGIN + DELETE TOP(@BatchSize) + FROM + [dbo].[Grant] + WHERE + [ExpirationDate] < @Now + + SET @BatchSize = @@ROWCOUNT + END +END +GO + +IF OBJECT_ID('[dbo].[User_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_Create] +END +GO + +CREATE PROCEDURE [dbo].[User_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @RenewalReminderDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[User] + ( + [Id], + [Name], + [Email], + [EmailVerified], + [MasterPassword], + [MasterPasswordHint], + [Culture], + [SecurityStamp], + [TwoFactorProviders], + [TwoFactorRecoveryCode], + [EquivalentDomains], + [ExcludedGlobalEquivalentDomains], + [AccountRevisionDate], + [Key], + [PublicKey], + [PrivateKey], + [Premium], + [PremiumExpirationDate], + [RenewalReminderDate], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [LicenseKey], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @Email, + @EmailVerified, + @MasterPassword, + @MasterPasswordHint, + @Culture, + @SecurityStamp, + @TwoFactorProviders, + @TwoFactorRecoveryCode, + @EquivalentDomains, + @ExcludedGlobalEquivalentDomains, + @AccountRevisionDate, + @Key, + @PublicKey, + @PrivateKey, + @Premium, + @PremiumExpirationDate, + @RenewalReminderDate, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @LicenseKey, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[User_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_Update] +END +GO + +CREATE PROCEDURE [dbo].[User_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @RenewalReminderDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[User] + SET + [Name] = @Name, + [Email] = @Email, + [EmailVerified] = @EmailVerified, + [MasterPassword] = @MasterPassword, + [MasterPasswordHint] = @MasterPasswordHint, + [Culture] = @Culture, + [SecurityStamp] = @SecurityStamp, + [TwoFactorProviders] = @TwoFactorProviders, + [TwoFactorRecoveryCode] = @TwoFactorRecoveryCode, + [EquivalentDomains] = @EquivalentDomains, + [ExcludedGlobalEquivalentDomains] = @ExcludedGlobalEquivalentDomains, + [AccountRevisionDate] = @AccountRevisionDate, + [Key] = @Key, + [PublicKey] = @PublicKey, + [PrivateKey] = @PrivateKey, + [Premium] = @Premium, + [PremiumExpirationDate] = @PremiumExpirationDate, + [RenewalReminderDate] = @RenewalReminderDate, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [LicenseKey] = @LicenseKey, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_UpdateRenewalReminderDate]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_UpdateRenewalReminderDate] +END +GO + +CREATE PROCEDURE [dbo].[User_UpdateRenewalReminderDate] + @Id UNIQUEIDENTIFIER, + @RenewalReminderDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[User] + SET + [RenewalReminderDate] = @RenewalReminderDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_ReadByPremiumRenewal]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_ReadByPremiumRenewal] +END +GO + +CREATE PROCEDURE [dbo].[User_ReadByPremiumRenewal] +AS +BEGIN + SET NOCOUNT ON + + DECLARE @WindowRef DATETIME2(7) = GETUTCDATE() + DECLARE @WindowStart DATETIME2(7) = DATEADD (day, -15, @WindowRef) + DECLARE @WindowEnd DATETIME2(7) = DATEADD (day, 15, @WindowRef) + + SELECT + * + FROM + [dbo].[UserView] + WHERE + [Premium] = 1 + AND [PremiumExpirationDate] >= @WindowRef + AND [PremiumExpirationDate] < @WindowEnd + AND ( + [RenewalReminderDate] IS NULL + OR [RenewalReminderDate] < @WindowStart + ) + AND [Gateway] = 1 -- Braintree +END +GO + +IF OBJECT_ID('[dbo].[Collection_ReadByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_ReadByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Collection_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + C.*, + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR CG.[ReadOnly] = 0 + THEN 0 + ELSE 1 + END [ReadOnly] + 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 + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[Organization_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + CREATE TABLE #OrgStorageUpdateTemp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #OrgStorageUpdateTemp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] IS NULL + AND [OrganizationId] = @Id + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + #OrgStorageUpdateTemp + ) + SELECT + @Storage = SUM([Size]) + FROM + [CTE] + + DROP TABLE #OrgStorageUpdateTemp + + UPDATE + [dbo].[Organization] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_UpdateStorage]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_UpdateStorage] +END +GO + +CREATE PROCEDURE [dbo].[User_UpdateStorage] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @Storage BIGINT + + CREATE TABLE #UserStorageUpdateTemp + ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [Attachments] VARCHAR(MAX) NULL + ) + + INSERT INTO #UserStorageUpdateTemp + SELECT + [Id], + [Attachments] + FROM + [dbo].[Cipher] + WHERE + [UserId] = @Id + + ;WITH [CTE] AS ( + SELECT + [Id], + ( + SELECT + SUM(CAST(JSON_VALUE(value,'$.Size') AS BIGINT)) + FROM + OPENJSON([Attachments]) + ) [Size] + FROM + #UserStorageUpdateTemp + ) + SELECT + @Storage = SUM([CTE].[Size]) + FROM + [CTE] + + DROP TABLE #UserStorageUpdateTemp + + UPDATE + [dbo].[User] + SET + [Storage] = @Storage, + [RevisionDate] = GETUTCDATE() + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollectionsForCiphers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsForCiphers] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsForCiphers] + @CipherIds AS [dbo].[GuidIdArray] READONLY, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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.[GroupId] = GU.[GroupId] + WHERE + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + RETURN + END + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Collection].[Id], + [Cipher].[Id] + FROM + @CollectionIds [Collection] + INNER JOIN + @CipherIds [Cipher] ON 1 = 1 + WHERE + [Collection].[Id] IN (SELECT [Id] FROM #AvailableCollections) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Folder_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Folder_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Folder_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @UserId UNIQUEIDENTIFIER = (SELECT TOP 1 [UserId] FROM [dbo].[Folder] WHERE [Id] = @Id) + DECLARE @UserIdPath VARCHAR(50) = CONCAT('$."', @UserId, '"') + + ;WITH [CTE] AS ( + SELECT + [Id], + [OrganizationId], + [AccessAll] + FROM + [OrganizationUser] + WHERE + [UserId] = @UserId + AND [Status] = 2 -- Confirmed + ) + UPDATE + C + SET + C.[Folders] = JSON_MODIFY(C.[Folders], @UserIdPath, NULL) + FROM + [dbo].[Cipher] C + INNER JOIN + [CTE] OU ON C.[UserId] IS NULL AND C.[OrganizationId] IN (SELECT [OrganizationId] FROM [CTE]) + INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] AND O.[Id] = C.[OrganizationId] AND O.[Enabled] = 1 + LEFT JOIN + [dbo].[CollectionCipher] CC ON OU.[AccessAll] = 0 AND CC.[CipherId] = C.[Id] + LEFT JOIN + [dbo].[CollectionUser] CU ON CU.[CollectionId] = CC.[CollectionId] 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] = CC.[CollectionId] AND CG.[GroupId] = GU.[GroupId] + WHERE + ( + OU.[AccessAll] = 1 + OR CU.[CollectionId] IS NOT NULL + OR G.[AccessAll] = 1 + OR CG.[CollectionId] IS NOT NULL + ) + AND JSON_VALUE(C.[Folders], @UserIdPath) = @Id + + UPDATE + C + SET + C.[Folders] = JSON_MODIFY(C.[Folders], @UserIdPath, NULL) + FROM + [dbo].[Cipher] C + WHERE + [UserId] = @UserId + AND JSON_VALUE([Folders], @UserIdPath) = @Id + + DELETE + FROM + [dbo].[Folder] + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDate] @UserId +END +GO + +IF OBJECT_ID('[dbo].[CollectionUserDetails_ReadByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] +END +GO + +CREATE PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + OU.[Id] AS [OrganizationUserId], + CASE + WHEN OU.[AccessAll] = 1 OR G.[AccessAll] = 1 THEN 1 + ELSE 0 + END [AccessAll], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + OU.[Status], + OU.[Type], + CASE + WHEN OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 0 + ELSE 1 + END [ReadOnly] + FROM + [dbo].[OrganizationUser] OU + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId + LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] + WHERE + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR ( + OU.[OrganizationId] = @OrganizationId + AND ( + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) + ) +END +GO diff --git a/src/Migrator/DbScripts/2018-07-28_00_DbTuning.sql b/src/Migrator/DbScripts/2018-07-28_00_DbTuning.sql new file mode 100644 index 000000000..311a48a08 --- /dev/null +++ b/src/Migrator/DbScripts/2018-07-28_00_DbTuning.sql @@ -0,0 +1,59 @@ +IF NOT EXISTS ( + SELECT * FROM sys.indexes WHERE [Name]='IX_OrganizationUser_OrganizationId' + AND object_id = OBJECT_ID('[dbo].[OrganizationUser]') +) +BEGIN + CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId] + ON [dbo].[OrganizationUser]([OrganizationId] ASC) +END +GO + +IF OBJECT_ID('[dbo].[CollectionUserDetails_ReadByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] +END +GO + +CREATE PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] + @CollectionId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + OU.[Id] AS [OrganizationUserId], + CASE + WHEN OU.[AccessAll] = 1 OR G.[AccessAll] = 1 THEN 1 + ELSE 0 + END [AccessAll], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + OU.[Status], + OU.[Type], + CASE + WHEN OU.[AccessAll] = 1 OR CU.[ReadOnly] = 0 OR G.[AccessAll] = 1 OR CG.[ReadOnly] = 0 THEN 0 + ELSE 1 + END [ReadOnly] + FROM + [dbo].[OrganizationUser] OU + LEFT JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = OU.[Id] AND CU.[CollectionId] = @CollectionId + 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.[GroupId] = GU.[GroupId] AND CG.[CollectionId] = @CollectionId + LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] + WHERE + OU.[OrganizationId] = @OrganizationId + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + ) +END +GO diff --git a/src/Migrator/DbScripts/2018-08-14_00_UserKdf.sql b/src/Migrator/DbScripts/2018-08-14_00_UserKdf.sql new file mode 100644 index 000000000..16ec43903 --- /dev/null +++ b/src/Migrator/DbScripts/2018-08-14_00_UserKdf.sql @@ -0,0 +1,495 @@ +IF COL_LENGTH('[dbo].[User]', 'Kdf') IS NULL +BEGIN + ALTER TABLE + [dbo].[User] + ADD + [Kdf] TINYINT NULL, + [KdfIterations] INT NULL +END +GO + +UPDATE + [dbo].[User] +SET + [Kdf] = 0, + [KdfIterations] = 5000 +GO + +ALTER TABLE + [dbo].[User] +ALTER COLUMN + [Kdf] TINYINT NOT NULL +GO + +ALTER TABLE + [dbo].[User] +ALTER COLUMN + [KdfIterations] INT NOT NULL +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'UserView') +BEGIN + DROP VIEW [dbo].[UserView] +END +GO + +CREATE VIEW [dbo].[UserView] +AS +SELECT + * +FROM + [dbo].[User] +GO + +IF OBJECT_ID('[dbo].[User_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_Create] +END +GO + +CREATE PROCEDURE [dbo].[User_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @RenewalReminderDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @Kdf TINYINT, + @KdfIterations INT, + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[User] + ( + [Id], + [Name], + [Email], + [EmailVerified], + [MasterPassword], + [MasterPasswordHint], + [Culture], + [SecurityStamp], + [TwoFactorProviders], + [TwoFactorRecoveryCode], + [EquivalentDomains], + [ExcludedGlobalEquivalentDomains], + [AccountRevisionDate], + [Key], + [PublicKey], + [PrivateKey], + [Premium], + [PremiumExpirationDate], + [RenewalReminderDate], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [LicenseKey], + [Kdf], + [KdfIterations], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @Email, + @EmailVerified, + @MasterPassword, + @MasterPasswordHint, + @Culture, + @SecurityStamp, + @TwoFactorProviders, + @TwoFactorRecoveryCode, + @EquivalentDomains, + @ExcludedGlobalEquivalentDomains, + @AccountRevisionDate, + @Key, + @PublicKey, + @PrivateKey, + @Premium, + @PremiumExpirationDate, + @RenewalReminderDate, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @LicenseKey, + @Kdf, + @KdfIterations, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[User_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_Update] +END +GO + +CREATE PROCEDURE [dbo].[User_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @Email NVARCHAR(50), + @EmailVerified BIT, + @MasterPassword NVARCHAR(300), + @MasterPasswordHint NVARCHAR(50), + @Culture NVARCHAR(10), + @SecurityStamp NVARCHAR(50), + @TwoFactorProviders NVARCHAR(MAX), + @TwoFactorRecoveryCode NVARCHAR(32), + @EquivalentDomains NVARCHAR(MAX), + @ExcludedGlobalEquivalentDomains NVARCHAR(MAX), + @AccountRevisionDate DATETIME2(7), + @Key NVARCHAR(MAX), + @PublicKey NVARCHAR(MAX), + @PrivateKey NVARCHAR(MAX), + @Premium BIT, + @PremiumExpirationDate DATETIME2(7), + @RenewalReminderDate DATETIME2(7), + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @LicenseKey VARCHAR(100), + @Kdf TINYINT, + @KdfIterations INT, + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[User] + SET + [Name] = @Name, + [Email] = @Email, + [EmailVerified] = @EmailVerified, + [MasterPassword] = @MasterPassword, + [MasterPasswordHint] = @MasterPasswordHint, + [Culture] = @Culture, + [SecurityStamp] = @SecurityStamp, + [TwoFactorProviders] = @TwoFactorProviders, + [TwoFactorRecoveryCode] = @TwoFactorRecoveryCode, + [EquivalentDomains] = @EquivalentDomains, + [ExcludedGlobalEquivalentDomains] = @ExcludedGlobalEquivalentDomains, + [AccountRevisionDate] = @AccountRevisionDate, + [Key] = @Key, + [PublicKey] = @PublicKey, + [PrivateKey] = @PrivateKey, + [Premium] = @Premium, + [PremiumExpirationDate] = @PremiumExpirationDate, + [RenewalReminderDate] = @RenewalReminderDate, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [LicenseKey] = @LicenseKey, + [Kdf] = @Kdf, + [KdfIterations] = @KdfIterations, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[User_ReadKdfByEmail]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_ReadKdfByEmail] +END +GO + +CREATE PROCEDURE [dbo].[User_ReadKdfByEmail] + @Email NVARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + [Kdf], + [KdfIterations] + FROM + [dbo].[User] + WHERE + [Email] = @Email +END +GO + +IF OBJECT_ID('[dbo].[Cipher_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateWithCollections] +END +GO + +CREATE 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), + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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 + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + SELECT -1 -- -1 = Failure + RETURN + END + + UPDATE + [dbo].[Cipher] + SET + [UserId] = NULL, + [OrganizationId] = @OrganizationId, + [Data] = @Data, + [Attachments] = @Attachments, + [RevisionDate] = @RevisionDate + -- No need to update CreationDate, Favorites, Folders, or Type since that data will not change + WHERE + [Id] = @Id + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Id], + @Id + FROM + @CollectionIds + WHERE + [Id] IN (SELECT [Id] FROM #AvailableCollections) + + 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 + +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollections] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollections] + @CipherId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Cipher] + WHERE + [Id] = @CipherId + ) + + ;WITH [AvailableCollectionsCTE] AS( + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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 + O.[Id] = @OrgId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + ) + MERGE + [dbo].[CollectionCipher] AS [Target] + USING + @CollectionIds AS [Source] + ON + [Target].[CollectionId] = [Source].[Id] + AND [Target].[CipherId] = @CipherId + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + INSERT VALUES + ( + [Source].[Id], + @CipherId + ) + WHEN NOT MATCHED BY SOURCE + AND [Target].[CipherId] = @CipherId + AND [Target].[CollectionId] IN (SELECT [Id] FROM [AvailableCollectionsCTE]) THEN + DELETE + ; + + IF @OrgId IS NOT NULL + BEGIN + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrgId + END +END +GO + +IF OBJECT_ID('[dbo].[CollectionCipher_UpdateCollectionsForCiphers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsForCiphers] +END +GO + +CREATE PROCEDURE [dbo].[CollectionCipher_UpdateCollectionsForCiphers] + @CipherIds AS [dbo].[GuidIdArray] READONLY, + @OrganizationId UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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 + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + RETURN + END + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Collection].[Id], + [Cipher].[Id] + FROM + @CollectionIds [Collection] + INNER JOIN + @CipherIds [Cipher] ON 1 = 1 + WHERE + [Collection].[Id] IN (SELECT [Id] FROM #AvailableCollections) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO diff --git a/src/Migrator/DbScripts/2018-08-28_00_PremiumOrgAbilities.sql b/src/Migrator/DbScripts/2018-08-28_00_PremiumOrgAbilities.sql new file mode 100644 index 000000000..e08ed0fa3 --- /dev/null +++ b/src/Migrator/DbScripts/2018-08-28_00_PremiumOrgAbilities.sql @@ -0,0 +1,27 @@ +IF OBJECT_ID('[dbo].[Organization_ReadAbilities]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_ReadAbilities] +END +GO + +CREATE PROCEDURE [dbo].[Organization_ReadAbilities] +AS +BEGIN + SET NOCOUNT ON + + SELECT + [Id], + [UseEvents], + [Use2fa], + CASE + WHEN [Use2fa] = 1 AND [TwoFactorProviders] IS NOT NULL AND [TwoFactorProviders] != '{}' THEN + 1 + ELSE + 0 + END AS [Using2fa], + [UsersGetPremium], + [Enabled] + FROM + [dbo].[Organization] +END +GO diff --git a/src/Migrator/DbScripts/2018-09-25_00_OrgPurge.sql b/src/Migrator/DbScripts/2018-09-25_00_OrgPurge.sql new file mode 100644 index 000000000..639738a2d --- /dev/null +++ b/src/Migrator/DbScripts/2018-09-25_00_OrgPurge.sql @@ -0,0 +1,292 @@ +IF OBJECT_ID('[dbo].[Cipher_DeleteByOrganizationId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_DeleteByOrganizationId] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_DeleteByOrganizationId] + @OrganizationId AS UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DECLARE @BatchSize INT = 100 + + -- Delete collection ciphers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION Cipher_DeleteByOrganizationId_CC + + DELETE TOP(@BatchSize) CC + FROM + [dbo].[CollectionCipher] CC + INNER JOIN + [dbo].[Collection] C ON C.[Id] = CC.[CollectionId] + WHERE + C.[OrganizationId] = @OrganizationId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION Cipher_DeleteByOrganizationId_CC + END + + -- Reset batch size + SET @BatchSize = 100 + + -- Delete ciphers + WHILE @BatchSize > 0 + BEGIN + BEGIN TRANSACTION Cipher_DeleteByOrganizationId + + DELETE TOP(@BatchSize) + FROM + [dbo].[Cipher] + WHERE + [OrganizationId] = @OrganizationId + + SET @BatchSize = @@ROWCOUNT + + COMMIT TRANSACTION Cipher_DeleteByOrganizationId + END + + -- Cleanup organization + EXEC [dbo].[Organization_UpdateStorage] @OrganizationId + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[AzureSQLMaintenance]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[AzureSQLMaintenance] +END +GO + +CREATE Procedure [dbo].[AzureSQLMaintenance] + ( + @operation nvarchar(10) = null, + @mode nvarchar(10) = 'smart', + @LogToTable bit = 0 + ) +as +begin + set nocount on + declare @msg nvarchar(max); + declare @minPageCountForIndex int = 40; + declare @OperationTime datetime2 = sysdatetime(); + declare @KeepXOperationInLog int =3; + + /* make sure parameters selected correctly */ + set @operation = lower(@operation) + set @mode = lower(@mode) + + if @mode not in ('smart','dummy') + set @mode = 'smart' + + if @operation not in ('index','statistics','all') or @operation is null + begin + raiserror('@operation (varchar(10)) [mandatory]',0,0) + raiserror(' Select operation to perform:',0,0) + raiserror(' "index" to perform index maintenance',0,0) + raiserror(' "statistics" to perform statistics maintenance',0,0) + raiserror(' "all" to perform indexes and statistics maintenance',0,0) + raiserror(' ',0,0) + raiserror('@mode(varchar(10)) [optional]',0,0) + raiserror(' optionaly you can supply second parameter for operation mode: ',0,0) + raiserror(' "smart" (Default) using smart decition about what index or stats should be touched.',0,0) + raiserror(' "dummy" going through all indexes and statistics regardless thier modifications or fragmentation.',0,0) + raiserror(' ',0,0) + raiserror('@LogToTable(bit) [optional]',0,0) + raiserror(' Logging option: @LogToTable(bit)',0,0) + raiserror(' 0 - (Default) do not log operation to table',0,0) + raiserror(' 1 - log operation to table',0,0) + raiserror(' for logging option only 3 last execution will be kept by default. this can be changed by easily in the procedure body.',0,0) + raiserror(' Log table will be created automatically if not exists.',0,0) + end + else + begin + /*Write operation parameters*/ + raiserror('-----------------------',0,0) + set @msg = 'set operation = ' + @operation; + raiserror(@msg,0,0) + set @msg = 'set mode = ' + @mode; + raiserror(@msg,0,0) + set @msg = 'set LogToTable = ' + cast(@LogToTable as varchar(1)); + raiserror(@msg,0,0) + raiserror('-----------------------',0,0) + end + + /* Prepare Log Table */ + if object_id('AzureSQLMaintenanceLog') is null + begin + create table AzureSQLMaintenanceLog (id bigint primary key identity(1,1), OperationTime datetime2, command varchar(4000),ExtraInfo varchar(4000), StartTime datetime2, EndTime datetime2, StatusMessage varchar(1000)); + end + + if @LogToTable=1 insert into AzureSQLMaintenanceLog values(@OperationTime,null,null,sysdatetime(),sysdatetime(),'Starting operation: Operation=' +@operation + ' Mode=' + @mode + ' Keep log for last ' + cast(@KeepXOperationInLog as varchar(10)) + ' operations' ) + + create table #cmdQueue (txtCMD nvarchar(max),ExtraInfo varchar(max)) + + + if @operation in('index','all') + begin + raiserror('Get index information...(wait)',0,0) with nowait; + /* Get Index Information */ + select + i.[object_id] + ,ObjectSchema = OBJECT_SCHEMA_NAME(i.object_id) + ,ObjectName = object_name(i.object_id) + ,IndexName = idxs.name + ,i.avg_fragmentation_in_percent + ,i.page_count + ,i.index_id + ,i.partition_number + ,i.index_type_desc + ,i.avg_page_space_used_in_percent + ,i.record_count + ,i.ghost_record_count + ,i.forwarded_record_count + ,null as OnlineOpIsNotSupported + into #idxBefore + from sys.dm_db_index_physical_stats(DB_ID(),NULL, NULL, NULL ,'limited') i + left join sys.indexes idxs on i.object_id = idxs.object_id and i.index_id = idxs.index_id + where idxs.type in (1/*Clustered index*/,2/*NonClustered index*/) /*Avoid HEAPS*/ + order by i.avg_fragmentation_in_percent desc, page_count desc + + + -- mark indexes XML,spatial and columnstore not to run online update + update #idxBefore set OnlineOpIsNotSupported=1 where [object_id] in (select [object_id] from #idxBefore where index_id >=1000) + + + raiserror('---------------------------------------',0,0) with nowait + raiserror('Index Information:',0,0) with nowait + raiserror('---------------------------------------',0,0) with nowait + + select @msg = count(*) from #idxBefore where index_id in (1,2) + set @msg = 'Total Indexes: ' + @msg + raiserror(@msg,0,0) with nowait + + select @msg = avg(avg_fragmentation_in_percent) from #idxBefore where index_id in (1,2) and page_count>@minPageCountForIndex + set @msg = 'Average Fragmentation: ' + @msg + raiserror(@msg,0,0) with nowait + + select @msg = sum(iif(avg_fragmentation_in_percent>=5 and page_count>@minPageCountForIndex,1,0)) from #idxBefore where index_id in (1,2) + set @msg = 'Fragmented Indexes: ' + @msg + raiserror(@msg,0,0) with nowait + + + raiserror('---------------------------------------',0,0) with nowait + + + + + /* create queue for update indexes */ + insert into #cmdQueue + select + txtCMD = + case when avg_fragmentation_in_percent>5 and avg_fragmentation_in_percent<30 and @mode = 'smart' then + 'ALTER INDEX [' + IndexName + '] ON [' + ObjectSchema + '].[' + ObjectName + '] REORGANIZE;' + when OnlineOpIsNotSupported=1 then + 'ALTER INDEX [' + IndexName + '] ON [' + ObjectSchema + '].[' + ObjectName + '] REBUILD WITH(ONLINE=OFF,MAXDOP=1);' + else + 'ALTER INDEX [' + IndexName + '] ON [' + ObjectSchema + '].[' + ObjectName + '] REBUILD WITH(ONLINE=ON,MAXDOP=1);' + end + , ExtraInfo = 'Current fragmentation: ' + format(avg_fragmentation_in_percent/100,'p') + from #idxBefore + where + index_id>0 /*disable heaps*/ + and index_id < 1000 /* disable XML indexes */ + -- + and + ( + page_count> @minPageCountForIndex and /* not small tables */ + avg_fragmentation_in_percent>=5 + ) + or + ( + @mode ='dummy' + ) + end + + if @operation in('statistics','all') + begin + /*Gets Stats for database*/ + raiserror('Get statistics information...',0,0) with nowait; + select + ObjectSchema = OBJECT_SCHEMA_NAME(s.object_id) + ,ObjectName = object_name(s.object_id) + ,StatsName = s.name + ,sp.last_updated + ,sp.rows + ,sp.rows_sampled + ,sp.modification_counter + into #statsBefore + from sys.stats s cross apply sys.dm_db_stats_properties(s.object_id,s.stats_id) sp + where OBJECT_SCHEMA_NAME(s.object_id) != 'sys' and (sp.modification_counter>0 or @mode='dummy') + order by sp.last_updated asc + + + raiserror('---------------------------------------',0,0) with nowait + raiserror('Statistics Information:',0,0) with nowait + raiserror('---------------------------------------',0,0) with nowait + + select @msg = sum(modification_counter) from #statsBefore + set @msg = 'Total Modifications: ' + @msg + raiserror(@msg,0,0) with nowait + + select @msg = sum(iif(modification_counter>0,1,0)) from #statsBefore + set @msg = 'Modified Statistics: ' + @msg + raiserror(@msg,0,0) with nowait + + raiserror('---------------------------------------',0,0) with nowait + + + + + /* create queue for update stats */ + insert into #cmdQueue + select + txtCMD = 'UPDATE STATISTICS [' + ObjectSchema + '].[' + ObjectName + '] (['+ StatsName +']) WITH FULLSCAN;' + , ExtraInfo = '#rows:' + cast([rows] as varchar(100)) + ' #modifications:' + cast(modification_counter as varchar(100)) + ' modification percent: ' + format((1.0 * modification_counter/ rows ),'p') + from #statsBefore + end + + + if @operation in('statistics','index','all') + begin + /* iterate through all stats */ + raiserror('Start executing commands...',0,0) with nowait + declare @SQLCMD nvarchar(max); + declare @ExtraInfo nvarchar(max); + declare @T table(txtCMD nvarchar(max),ExtraInfo nvarchar(max)); + while exists(select * from #cmdQueue) + begin + delete top (1) from #cmdQueue output deleted.* into @T; + select top (1) @SQLCMD = txtCMD, @ExtraInfo=ExtraInfo from @T + raiserror(@SQLCMD,0,0) with nowait + if @LogToTable=1 insert into AzureSQLMaintenanceLog values(@OperationTime,@SQLCMD,@ExtraInfo,sysdatetime(),null,'Started') + begin try + exec(@SQLCMD) + if @LogToTable=1 update AzureSQLMaintenanceLog set EndTime = sysdatetime(), StatusMessage = 'Succeeded' where id=SCOPE_IDENTITY() + end try + begin catch + raiserror('cached',0,0) with nowait + if @LogToTable=1 update AzureSQLMaintenanceLog set EndTime = sysdatetime(), StatusMessage = 'FAILED : ' + CAST(ERROR_NUMBER() AS VARCHAR(50)) + ERROR_MESSAGE() where id=SCOPE_IDENTITY() + end catch + delete from @T + end + end + + /* Clean old records from log table */ + if @LogToTable=1 + begin + delete from AzureSQLMaintenanceLog + from + AzureSQLMaintenanceLog L join + (select distinct OperationTime from AzureSQLMaintenanceLog order by OperationTime desc offset @KeepXOperationInLog rows) F + ON L.OperationTime = F.OperationTime + insert into AzureSQLMaintenanceLog values(@OperationTime,null,cast(@@rowcount as varchar(100))+ ' rows purged from log table because number of operations to keep is set to: ' + cast( @KeepXOperationInLog as varchar(100)),sysdatetime(),sysdatetime(),'Cleanup Log Table') + end + + raiserror('Done',0,0) + if @LogToTable=1 insert into AzureSQLMaintenanceLog values(@OperationTime,null,null,sysdatetime(),sysdatetime(),'End of operation') +end +GO diff --git a/src/Migrator/DbScripts/2018-10-17_00_ManagerRole.sql b/src/Migrator/DbScripts/2018-10-17_00_ManagerRole.sql new file mode 100644 index 000000000..fad3155bf --- /dev/null +++ b/src/Migrator/DbScripts/2018-10-17_00_ManagerRole.sql @@ -0,0 +1,550 @@ +ALTER TABLE [dbo].[Group] ALTER COLUMN [Name] NVARCHAR (100) NOT NULL +GO + +IF OBJECT_ID('[dbo].[UserCollectionDetails]') IS NOT NULL +BEGIN + DROP FUNCTION [dbo].[UserCollectionDetails] +END +GO + +CREATE FUNCTION [dbo].[UserCollectionDetails](@UserId UNIQUEIDENTIFIER) +RETURNS TABLE +AS RETURN +SELECT + C.*, + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR CG.[ReadOnly] = 0 + THEN 0 + ELSE 1 + END [ReadOnly] +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 + +IF OBJECT_ID('[dbo].[Collection_ReadByIdUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_ReadByIdUserId] +END +GO + +CREATE PROCEDURE [dbo].[Collection_ReadByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + SELECT TOP 1 + * + FROM + [dbo].[UserCollectionDetails](@UserId) + WHERE + [Id] = @Id + ORDER BY + [ReadOnly] ASC +END +GO + +IF OBJECT_ID('[dbo].[Collection_ReadByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_ReadByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Collection_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[UserCollectionDetails](@UserId) +END +GO + +IF OBJECT_ID('[dbo].[Collection_ReadWithGroupsByIdUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_ReadWithGroupsByIdUserId] +END +GO + +CREATE PROCEDURE [dbo].[Collection_ReadWithGroupsByIdUserId] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_ReadByIdUserId] @Id, @UserId + + SELECT + [GroupId] [Id], + [ReadOnly] + FROM + [dbo].[CollectionGroup] + WHERE + [CollectionId] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Collection_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_UpdateUsers] +END +GO + +IF OBJECT_ID('[dbo].[CollectionUser_UpdateUsers]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUser_UpdateUsers] +END +GO + +CREATE PROCEDURE [dbo].[CollectionUser_UpdateUsers] + @CollectionId UNIQUEIDENTIFIER, + @Users AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + DECLARE @OrgId UNIQUEIDENTIFIER = ( + SELECT TOP 1 + [OrganizationId] + FROM + [dbo].[Collection] + WHERE + [Id] = @CollectionId + ) + + ;WITH [AvailableUsersCTE] AS( + SELECT + Id + FROM + [dbo].[OrganizationUser] + WHERE + OrganizationId = @OrgId + ) + MERGE + [dbo].[CollectionUser] AS [Target] + USING + @Users AS [Source] + ON + [Target].[CollectionId] = @CollectionId + AND [Target].[OrganizationUserId] = [Source].[Id] + WHEN NOT MATCHED BY TARGET + AND [Source].[Id] IN (SELECT [Id] FROM [AvailableUsersCTE]) THEN + INSERT VALUES + ( + @CollectionId, + [Source].[Id], + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @CollectionId THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @CollectionId, @OrgId +END +GO + +IF OBJECT_ID('[dbo].[CollectionUserDetails_ReadByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUserDetails_ReadByCollectionId] +END +GO + +IF OBJECT_ID('[dbo].[CollectionUser_ReadByCollectionId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CollectionUser_ReadByCollectionId] +END +GO + +CREATE PROCEDURE [dbo].[CollectionUser_ReadByCollectionId] + @CollectionId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + [OrganizationUserId] [Id], + [ReadOnly] + FROM + [dbo].[CollectionUser] + WHERE + [CollectionId] = @CollectionId +END +GO + +IF OBJECT_ID('[dbo].[GroupUserDetails_ReadByGroupId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[GroupUserDetails_ReadByGroupId] +END +GO + +IF OBJECT_ID('[dbo].[GroupUser_ReadOrganizationUserIdsByGroupId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[GroupUser_ReadOrganizationUserIdsByGroupId] +END +GO + +CREATE PROCEDURE [dbo].[GroupUser_ReadOrganizationUserIdsByGroupId] + @GroupId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + [OrganizationUserId] + FROM + [dbo].[GroupUser] + WHERE + [GroupId] = @GroupId +END +GO + +IF OBJECT_ID('[dbo].[Cipher_UpdateCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateCollections] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_UpdateCollections] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + IF @OrganizationId IS NULL OR (SELECT COUNT(1) FROM @CollectionIds) < 1 + BEGIN + RETURN(-1) + END + + CREATE TABLE #AvailableCollections ( + [Id] UNIQUEIDENTIFIER + ) + + IF @UserId IS NULL + BEGIN + INSERT INTO #AvailableCollections + SELECT + [Id] + FROM + [dbo].[Collection] + WHERE + [OrganizationId] = @OrganizationId + END + ELSE + BEGIN + INSERT INTO #AvailableCollections + SELECT + C.[Id] + FROM + [dbo].[Collection] C + INNER JOIN + [Organization] O ON O.[Id] = C.[OrganizationId] + INNER JOIN + [dbo].[OrganizationUser] OU ON OU.[OrganizationId] = O.[Id] AND OU.[UserId] = @UserId + 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 + O.[Id] = @OrganizationId + AND O.[Enabled] = 1 + AND OU.[Status] = 2 -- Confirmed + AND ( + OU.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR G.[AccessAll] = 1 + OR CG.[ReadOnly] = 0 + ) + END + + IF (SELECT COUNT(1) FROM #AvailableCollections) < 1 + BEGIN + -- No writable collections available to share with in this organization. + RETURN(-1) + END + + INSERT INTO [dbo].[CollectionCipher] + ( + [CollectionId], + [CipherId] + ) + SELECT + [Id], + @Id + FROM + @CollectionIds + WHERE + [Id] IN (SELECT [Id] FROM #AvailableCollections) + + RETURN(0) +END +GO + +IF OBJECT_ID('[dbo].[CipherDetails_CreateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[CipherDetails_CreateWithCollections] +END +GO + +CREATE 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 + @OrganizationUseTotp BIT, -- not used + @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, @OrganizationUseTotp + + DECLARE @UpdateCollectionsSuccess INT + EXEC @UpdateCollectionsSuccess = [dbo].[Cipher_UpdateCollections] @Id, @UserId, @OrganizationId, @CollectionIds +END +GO + +IF OBJECT_ID('[dbo].[Cipher_CreateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_CreateWithCollections] +END +GO + +CREATE 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), + @CollectionIds AS [dbo].[GuidIdArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Cipher_Create] @Id, @UserId, @OrganizationId, @Type, @Data, @Favorites, @Folders, + @Attachments, @CreationDate, @RevisionDate + + DECLARE @UpdateCollectionsSuccess INT + EXEC @UpdateCollectionsSuccess = [dbo].[Cipher_UpdateCollections] @Id, @UserId, @OrganizationId, @CollectionIds +END +GO + +IF OBJECT_ID('[dbo].[Cipher_UpdateWithCollections]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_UpdateWithCollections] +END +GO + +CREATE 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), + @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 + -- 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 + +IF OBJECT_ID('[dbo].[Cipher_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_Create] +END +GO + +CREATE PROCEDURE [dbo].[Cipher_Create] + @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) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Cipher] + ( + [Id], + [UserId], + [OrganizationId], + [Type], + [Data], + [Favorites], + [Folders], + [Attachments], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + CASE WHEN @OrganizationId IS NULL THEN @UserId ELSE NULL END, + @OrganizationId, + @Type, + @Data, + @Favorites, + @Folders, + @Attachments, + @CreationDate, + @RevisionDate + ) + + 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 + +IF OBJECT_ID('[dbo].[Cipher_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Cipher_Update] +END +GO + +CREATE 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) +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 + 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 diff --git a/src/Migrator/DbScripts/2018-12-19_00_OrgUserTwoFactorEnabled.sql b/src/Migrator/DbScripts/2018-12-19_00_OrgUserTwoFactorEnabled.sql new file mode 100644 index 000000000..d5a5b2b67 --- /dev/null +++ b/src/Migrator/DbScripts/2018-12-19_00_OrgUserTwoFactorEnabled.sql @@ -0,0 +1,25 @@ +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationUserUserDetailsView') +BEGIN + DROP VIEW [dbo].[OrganizationUserUserDetailsView] +END +GO + +CREATE VIEW [dbo].[OrganizationUserUserDetailsView] +AS +SELECT + OU.[Id], + OU.[UserId], + OU.[OrganizationId], + U.[Name], + ISNULL(U.[Email], OU.[Email]) Email, + U.[TwoFactorProviders], + U.[Premium], + OU.[Status], + OU.[Type], + OU.[AccessAll], + OU.[ExternalId] +FROM + [dbo].[OrganizationUser] OU +LEFT JOIN + [dbo].[User] U ON U.[Id] = OU.[UserId] +GO diff --git a/src/Migrator/DbScripts/2019-01-31_00_Transactions.sql b/src/Migrator/DbScripts/2019-01-31_00_Transactions.sql new file mode 100644 index 000000000..274a1c5d4 --- /dev/null +++ b/src/Migrator/DbScripts/2019-01-31_00_Transactions.sql @@ -0,0 +1,253 @@ +IF OBJECT_ID('[dbo].[Transaction]') IS NULL +BEGIN + CREATE TABLE [dbo].[Transaction] ( + [Id] UNIQUEIDENTIFIER NOT NULL, + [UserId] UNIQUEIDENTIFIER NULL, + [OrganizationId] UNIQUEIDENTIFIER NULL, + [Type] TINYINT NOT NULL, + [Amount] MONEY NOT NULL, + [Refunded] BIT NULL, + [RefundedAmount] MONEY NULL, + [Details] NVARCHAR(100) NULL, + [PaymentMethodType] TINYINT NULL, + [Gateway] TINYINT NULL, + [GatewayId] VARCHAR(50) NULL, + [CreationDate] DATETIME2 (7) NOT NULL, + CONSTRAINT [PK_Transaction] PRIMARY KEY CLUSTERED ([Id] ASC), + CONSTRAINT [FK_Transaction_User] FOREIGN KEY ([UserId]) REFERENCES [dbo].[User] ([Id]) ON DELETE CASCADE, + CONSTRAINT [FK_Transaction_Organization] FOREIGN KEY ([OrganizationId]) REFERENCES [dbo].[Organization] ([Id]) ON DELETE CASCADE + ); + + CREATE UNIQUE NONCLUSTERED INDEX [IX_Transaction_Gateway_GatewayId] + ON [dbo].[Transaction]([Gateway] ASC, [GatewayId] ASC) + WHERE [Gateway] IS NOT NULL AND [GatewayId] IS NOT NULL; + + CREATE NONCLUSTERED INDEX [IX_Transaction_UserId_OrganizationId_CreationDate] + ON [dbo].[Transaction]([UserId] ASC, [OrganizationId] ASC, [CreationDate] ASC); +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'TransactionView') +BEGIN + DROP VIEW [dbo].[TransactionView] +END +GO + +CREATE VIEW [dbo].[TransactionView] +AS +SELECT + * +FROM + [dbo].[Transaction] +GO + +IF OBJECT_ID('[dbo].[Transaction_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_Create] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_Create] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Type TINYINT, + @Amount MONEY, + @Refunded BIT, + @RefundedAmount MONEY, + @Details NVARCHAR(100), + @PaymentMethodType TINYINT, + @Gateway TINYINT, + @GatewayId VARCHAR(50), + @CreationDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Transaction] + ( + [Id], + [UserId], + [OrganizationId], + [Type], + [Amount], + [Refunded], + [RefundedAmount], + [Details], + [PaymentMethodType], + [Gateway], + [GatewayId], + [CreationDate] + ) + VALUES + ( + @Id, + @UserId, + @OrganizationId, + @Type, + @Amount, + @Refunded, + @RefundedAmount, + @Details, + @PaymentMethodType, + @Gateway, + @GatewayId, + @CreationDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Transaction_DeleteById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_DeleteById] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_DeleteById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + DELETE + FROM + [dbo].[Transaction] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Transaction_ReadById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_ReadById] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[TransactionView] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Transaction_ReadByOrganizationId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_ReadByOrganizationId] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_ReadByOrganizationId] + @OrganizationId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[TransactionView] + WHERE + [UserId] IS NULL + AND [OrganizationId] = @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Transaction_ReadByUserId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_ReadByUserId] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_ReadByUserId] + @UserId UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[TransactionView] + WHERE + [UserId] = @UserId +END +GO + +IF OBJECT_ID('[dbo].[Transaction_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_Update] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_Update] + @Id UNIQUEIDENTIFIER, + @UserId UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Type TINYINT, + @Amount MONEY, + @Refunded BIT, + @RefundedAmount MONEY, + @Details NVARCHAR(100), + @PaymentMethodType TINYINT, + @Gateway TINYINT, + @GatewayId VARCHAR(50), + @CreationDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Transaction] + SET + [UserId] = @UserId, + [OrganizationId] = @OrganizationId, + [Type] = @Type, + [Amount] = @Amount, + [Refunded] = @Refunded, + [RefundedAmount] = @RefundedAmount, + [Details] = @Details, + [PaymentMethodType] = @PaymentMethodType, + [Gateway] = @Gateway, + [GatewayId] = @GatewayId, + [CreationDate] = @CreationDate + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[Transaction_ReadByGatewayId]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Transaction_ReadByGatewayId] +END +GO + +CREATE PROCEDURE [dbo].[Transaction_ReadByGatewayId] + @Gateway TINYINT, + @GatewayId VARCHAR(50) +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[TransactionView] + WHERE + [Gateway] = @Gateway + AND [GatewayId] = @GatewayId +END +GO + +IF OBJECT_ID('[dbo].[User_ReadByPremiumRenewal]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[User_ReadByPremiumRenewal] +END +GO diff --git a/src/Migrator/DbScripts/2019-03-01_00_OrgApi.sql b/src/Migrator/DbScripts/2019-03-01_00_OrgApi.sql new file mode 100644 index 000000000..83d41b3e4 --- /dev/null +++ b/src/Migrator/DbScripts/2019-03-01_00_OrgApi.sql @@ -0,0 +1,628 @@ +-- Setup for random string generation + +CREATE VIEW [dbo].[SecureRandomBytes] +AS +SELECT [RandBytes] = CRYPT_GEN_RANDOM(2) +GO + +CREATE FUNCTION [dbo].[SecureRandomString]() +RETURNS varchar(30) +AS +BEGIN + declare @sLength tinyint + declare @randomString varchar(30) + declare @counter tinyint + declare @nextChar char(1) + declare @rnd as float + declare @bytes binary(2) + + set @sLength = 30 + set @counter = 1 + set @randomString = '' + + while @counter <= @sLength + begin + select @bytes = [RandBytes] from [dbo].[SecureRandomBytes] + select @rnd = cast(cast(cast(@bytes as int) as float) / 65535 as float) + select @nextChar = char(48 + convert(int, (122-48+1) * @rnd)) + if ascii(@nextChar) not in (58,59,60,61,62,63,64,91,92,93,94,95,96) + begin + select @randomString = @randomString + @nextChar + set @counter = @counter + 1 + end + end + return @randomString +END +GO + +-- End setup + +IF COL_LENGTH('[dbo].[Organization]', 'UseApi') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [UseApi] BIT NULL +END +GO + +UPDATE + [dbo].[Organization] +SET + [UseApi] = (CASE WHEN [PlanType] = 5 OR [PlanType] = 4 THEN 1 ELSE 0 END) +GO + +ALTER TABLE + [dbo].[Organization] +ALTER COLUMN + [UseApi] BIT NOT NULL +GO + +IF COL_LENGTH('[dbo].[Organization]', 'ApiKey') IS NULL +BEGIN + ALTER TABLE + [dbo].[Organization] + ADD + [ApiKey] VARCHAR(30) NULL +END +GO + +UPDATE + [dbo].[Organization] +SET + [ApiKey] = (SELECT [dbo].[SecureRandomString]()) +GO + +ALTER TABLE + [dbo].[Organization] +ALTER COLUMN + [ApiKey] VARCHAR(30) NOT NULL +GO + +-- Cleanup random string generation + +DROP VIEW [dbo].[SecureRandomBytes] +GO +DROP FUNCTION [dbo].[SecureRandomString] +GO + +-- End + +IF OBJECT_ID('[dbo].[Organization_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Create] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Create] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @Use2fa BIT, + @UseApi BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ApiKey VARCHAR(30), + @TwoFactorProviders NVARCHAR(MAX), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Organization] + ( + [Id], + [Name], + [BusinessName], + [BusinessAddress1], + [BusinessAddress2], + [BusinessAddress3], + [BusinessCountry], + [BusinessTaxNumber], + [BillingEmail], + [Plan], + [PlanType], + [Seats], + [MaxCollections], + [UseGroups], + [UseDirectory], + [UseEvents], + [UseTotp], + [Use2fa], + [UseApi], + [SelfHost], + [UsersGetPremium], + [Storage], + [MaxStorageGb], + [Gateway], + [GatewayCustomerId], + [GatewaySubscriptionId], + [Enabled], + [LicenseKey], + [ApiKey], + [TwoFactorProviders], + [ExpirationDate], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @Name, + @BusinessName, + @BusinessAddress1, + @BusinessAddress2, + @BusinessAddress3, + @BusinessCountry, + @BusinessTaxNumber, + @BillingEmail, + @Plan, + @PlanType, + @Seats, + @MaxCollections, + @UseGroups, + @UseDirectory, + @UseEvents, + @UseTotp, + @Use2fa, + @UseApi, + @SelfHost, + @UsersGetPremium, + @Storage, + @MaxStorageGb, + @Gateway, + @GatewayCustomerId, + @GatewaySubscriptionId, + @Enabled, + @LicenseKey, + @ApiKey, + @TwoFactorProviders, + @ExpirationDate, + @CreationDate, + @RevisionDate + ) +END +GO + +IF OBJECT_ID('[dbo].[Organization_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Organization_Update] +END +GO + +CREATE PROCEDURE [dbo].[Organization_Update] + @Id UNIQUEIDENTIFIER, + @Name NVARCHAR(50), + @BusinessName NVARCHAR(50), + @BusinessAddress1 NVARCHAR(50), + @BusinessAddress2 NVARCHAR(50), + @BusinessAddress3 NVARCHAR(50), + @BusinessCountry VARCHAR(2), + @BusinessTaxNumber NVARCHAR(30), + @BillingEmail NVARCHAR(50), + @Plan NVARCHAR(50), + @PlanType TINYINT, + @Seats SMALLINT, + @MaxCollections SMALLINT, + @UseGroups BIT, + @UseDirectory BIT, + @UseEvents BIT, + @UseTotp BIT, + @Use2fa BIT, + @UseApi BIT, + @SelfHost BIT, + @UsersGetPremium BIT, + @Storage BIGINT, + @MaxStorageGb SMALLINT, + @Gateway TINYINT, + @GatewayCustomerId VARCHAR(50), + @GatewaySubscriptionId VARCHAR(50), + @Enabled BIT, + @LicenseKey VARCHAR(100), + @ApiKey VARCHAR(30), + @TwoFactorProviders NVARCHAR(MAX), + @ExpirationDate DATETIME2(7), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Organization] + SET + [Name] = @Name, + [BusinessName] = @BusinessName, + [BusinessAddress1] = @BusinessAddress1, + [BusinessAddress2] = @BusinessAddress2, + [BusinessAddress3] = @BusinessAddress3, + [BusinessCountry] = @BusinessCountry, + [BusinessTaxNumber] = @BusinessTaxNumber, + [BillingEmail] = @BillingEmail, + [Plan] = @Plan, + [PlanType] = @PlanType, + [Seats] = @Seats, + [MaxCollections] = @MaxCollections, + [UseGroups] = @UseGroups, + [UseDirectory] = @UseDirectory, + [UseEvents] = @UseEvents, + [UseTotp] = @UseTotp, + [Use2fa] = @Use2fa, + [UseApi] = @UseApi, + [SelfHost] = @SelfHost, + [UsersGetPremium] = @UsersGetPremium, + [Storage] = @Storage, + [MaxStorageGb] = @MaxStorageGb, + [Gateway] = @Gateway, + [GatewayCustomerId] = @GatewayCustomerId, + [GatewaySubscriptionId] = @GatewaySubscriptionId, + [Enabled] = @Enabled, + [LicenseKey] = @LicenseKey, + [ApiKey] = @ApiKey, + [TwoFactorProviders] = @TwoFactorProviders, + [ExpirationDate] = @ExpirationDate, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationView') +BEGIN + DROP VIEW [dbo].[OrganizationView] +END +GO + +CREATE VIEW [dbo].[OrganizationView] +AS +SELECT + * +FROM + [dbo].[Organization] +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'OrganizationUserOrganizationDetailsView') +BEGIN + DROP VIEW [dbo].[OrganizationUserOrganizationDetailsView] +END +GO + +CREATE VIEW [dbo].[OrganizationUserOrganizationDetailsView] +AS +SELECT + OU.[UserId], + OU.[OrganizationId], + O.[Name], + O.[Enabled], + O.[UseGroups], + O.[UseDirectory], + O.[UseEvents], + O.[UseTotp], + O.[Use2fa], + O.[UseApi], + O.[SelfHost], + O.[UsersGetPremium], + O.[Seats], + O.[MaxCollections], + O.[MaxStorageGb], + OU.[Key], + OU.[Status], + OU.[Type] +FROM + [dbo].[OrganizationUser] OU +INNER JOIN + [dbo].[Organization] O ON O.[Id] = OU.[OrganizationId] +GO + +IF OBJECT_ID('[dbo].[OrganizationUserUserDetails_ReadById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUserUserDetails_ReadById] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUserUserDetails_ReadById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + SELECT + * + FROM + [dbo].[OrganizationUserUserDetailsView] + WHERE + [Id] = @Id +END +GO + +IF OBJECT_ID('[dbo].[OrganizationUserUserDetails_ReadWithCollectionsById]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[OrganizationUserUserDetails_ReadWithCollectionsById] +END +GO + +CREATE PROCEDURE [dbo].[OrganizationUserUserDetails_ReadWithCollectionsById] + @Id UNIQUEIDENTIFIER +AS +BEGIN + SET NOCOUNT ON + + EXEC [OrganizationUserUserDetails_ReadById] @Id + + SELECT + CU.[CollectionId] Id, + CU.[ReadOnly] + FROM + [dbo].[OrganizationUser] OU + INNER JOIN + [dbo].[CollectionUser] CU ON OU.[AccessAll] = 0 AND CU.[OrganizationUserId] = [OU].[Id] + WHERE + [OrganizationUserId] = @Id +END +GO + +IF COL_LENGTH('[dbo].[Collection]', 'ExternalId') IS NULL +BEGIN + ALTER TABLE + [dbo].[Collection] + ADD + [ExternalId] NVARCHAR(300) NULL +END +GO + +IF OBJECT_ID('[dbo].[Collection_Create]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_Create] +END +GO + +CREATE PROCEDURE [dbo].[Collection_Create] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + INSERT INTO [dbo].[Collection] + ( + [Id], + [OrganizationId], + [Name], + [ExternalId], + [CreationDate], + [RevisionDate] + ) + VALUES + ( + @Id, + @OrganizationId, + @Name, + @ExternalId, + @CreationDate, + @RevisionDate + ) + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_Update]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_Update] +END +GO + +CREATE PROCEDURE [dbo].[Collection_Update] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7) +AS +BEGIN + SET NOCOUNT ON + + UPDATE + [dbo].[Collection] + SET + [OrganizationId] = @OrganizationId, + [Name] = @Name, + [ExternalId] = @ExternalId, + [CreationDate] = @CreationDate, + [RevisionDate] = @RevisionDate + WHERE + [Id] = @Id + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_CreateWithGroups]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_CreateWithGroups] +END +GO + +CREATE PROCEDURE [dbo].[Collection_CreateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Create] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + ;WITH [AvailableGroupsCTE] AS( + SELECT + [Id] + FROM + [dbo].[Group] + WHERE + [OrganizationId] = @OrganizationId + ) + INSERT INTO [dbo].[CollectionGroup] + ( + [CollectionId], + [GroupId], + [ReadOnly] + ) + SELECT + @Id, + [Id], + [ReadOnly] + FROM + @Groups + WHERE + [Id] IN (SELECT [Id] FROM [AvailableGroupsCTE]) + + EXEC [dbo].[User_BumpAccountRevisionDateByOrganizationId] @OrganizationId +END +GO + +IF OBJECT_ID('[dbo].[Collection_UpdateWithGroups]') IS NOT NULL +BEGIN + DROP PROCEDURE [dbo].[Collection_UpdateWithGroups] +END +GO + +CREATE PROCEDURE [dbo].[Collection_UpdateWithGroups] + @Id UNIQUEIDENTIFIER, + @OrganizationId UNIQUEIDENTIFIER, + @Name VARCHAR(MAX), + @ExternalId NVARCHAR(300), + @CreationDate DATETIME2(7), + @RevisionDate DATETIME2(7), + @Groups AS [dbo].[SelectionReadOnlyArray] READONLY +AS +BEGIN + SET NOCOUNT ON + + EXEC [dbo].[Collection_Update] @Id, @OrganizationId, @Name, @ExternalId, @CreationDate, @RevisionDate + + ;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 VALUES + ( + @Id, + [Source].[Id], + [Source].[ReadOnly] + ) + WHEN MATCHED AND [Target].[ReadOnly] != [Source].[ReadOnly] THEN + UPDATE SET [Target].[ReadOnly] = [Source].[ReadOnly] + WHEN NOT MATCHED BY SOURCE + AND [Target].[CollectionId] = @Id THEN + DELETE + ; + + EXEC [dbo].[User_BumpAccountRevisionDateByCollectionId] @Id, @OrganizationId +END +GO + +IF EXISTS(SELECT * FROM sys.views WHERE [Name] = 'CollectionView') +BEGIN + DROP VIEW [dbo].[CollectionView] +END +GO + +CREATE VIEW [dbo].[CollectionView] +AS +SELECT + * +FROM + [dbo].[Collection] +GO + +IF OBJECT_ID('[dbo].[UserCollectionDetails]') IS NOT NULL +BEGIN + DROP FUNCTION [dbo].[UserCollectionDetails] +END +GO + +CREATE FUNCTION [dbo].[UserCollectionDetails](@UserId UNIQUEIDENTIFIER) +RETURNS TABLE +AS RETURN +SELECT + C.*, + CASE + WHEN + OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 + OR CU.[ReadOnly] = 0 + OR CG.[ReadOnly] = 0 + THEN 0 + ELSE 1 + END [ReadOnly] +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 diff --git a/src/Migrator/Migrator.csproj b/src/Migrator/Migrator.csproj new file mode 100644 index 000000000..97e84b05c --- /dev/null +++ b/src/Migrator/Migrator.csproj @@ -0,0 +1,16 @@ + + + + netcoreapp2.1 + Bit.Migrator + + + + + + + + + + +