From 98fc54881be27a9e994917e4854b10c4ea9daba6 Mon Sep 17 00:00:00 2001 From: Kyle Spearrin Date: Sat, 28 Jul 2018 21:25:25 -0400 Subject: [PATCH] database tuning --- ...llectionUserDetails_ReadByCollectionId.sql | 14 ++--- src/Sql/dbo/Tables/OrganizationUser.sql | 5 ++ .../DbScripts/2018-07-28_00_DbTuning.sql | 59 +++++++++++++++++++ util/Setup/Setup.csproj | 2 + 4 files changed, 72 insertions(+), 8 deletions(-) create mode 100644 util/Setup/DbScripts/2018-07-28_00_DbTuning.sql diff --git a/src/Sql/dbo/Stored Procedures/CollectionUserDetails_ReadByCollectionId.sql b/src/Sql/dbo/Stored Procedures/CollectionUserDetails_ReadByCollectionId.sql index 82492b2ec7..90bec45851 100644 --- a/src/Sql/dbo/Stored Procedures/CollectionUserDetails_ReadByCollectionId.sql +++ b/src/Sql/dbo/Stored Procedures/CollectionUserDetails_ReadByCollectionId.sql @@ -32,13 +32,11 @@ BEGIN 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 - ) + OU.[OrganizationId] = @OrganizationId + AND ( + CU.[CollectionId] IS NOT NULL + OR CG.[CollectionId] IS NOT NULL + OR OU.[AccessAll] = 1 + OR G.[AccessAll] = 1 ) END \ No newline at end of file diff --git a/src/Sql/dbo/Tables/OrganizationUser.sql b/src/Sql/dbo/Tables/OrganizationUser.sql index bc7bd327c3..6b708bf573 100644 --- a/src/Sql/dbo/Tables/OrganizationUser.sql +++ b/src/Sql/dbo/Tables/OrganizationUser.sql @@ -21,3 +21,8 @@ CREATE NONCLUSTERED INDEX [IX_OrganizationUser_UserIdOrganizationIdStatus] ON [dbo].[OrganizationUser]([UserId] ASC, [OrganizationId] ASC, [Status] ASC) INCLUDE ([AccessAll]); + +GO +CREATE NONCLUSTERED INDEX [IX_OrganizationUser_OrganizationId] + ON [dbo].[OrganizationUser]([OrganizationId] ASC); + diff --git a/util/Setup/DbScripts/2018-07-28_00_DbTuning.sql b/util/Setup/DbScripts/2018-07-28_00_DbTuning.sql new file mode 100644 index 0000000000..311a48a082 --- /dev/null +++ b/util/Setup/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/util/Setup/Setup.csproj b/util/Setup/Setup.csproj index e7fc950459..a65887ddbc 100644 --- a/util/Setup/Setup.csproj +++ b/util/Setup/Setup.csproj @@ -11,9 +11,11 @@ + +