Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Performance fix for CoreMessaging_GetMessageConversations and Journal_ListForGroup Procedure #2342

Merged
merged 1 commit into from
Oct 3, 2018
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -101,6 +101,142 @@ END

GO



/* Fix GetMessageConversations Procedure */
/*****************************************/
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}[{objectQualifier}CoreMessaging_GetMessageConversations]') AND type in (N'P', N'PC'))
DROP PROCEDURE {databaseOwner}[{objectQualifier}CoreMessaging_GetMessageConversations]
GO
CREATE PROCEDURE {databaseOwner}[{objectQualifier}CoreMessaging_GetMessageConversations]
@UserID int,
@PortalID int,
@AfterMessageID int,
@NumberOfRecords int,
@SortField nvarchar(25) = 'CreatedOnDate',
@SortAscending bit = 0,
@Read bit = 0,
@Archived bit = 0,
@SentOnly bit = 0
AS
BEGIN
--Get the top message for each conversation
;WITH RollUpMessageIDs AS
(
SELECT MAX(m.MessageID) AS TopMessageID
FROM {databaseOwner}[{objectQualifier}CoreMessaging_MessageRecipients] mr
INNER JOIN {databaseOwner}[{objectQualifier}CoreMessaging_Messages] m ON mr.MessageID = m.MessageID
WHERE ((Archived = @Archived) or (@Archived is null AND [Archived] IS NOT null))
AND (([Read] = @Read) or (@Read is null AND [READ] IS NOT null))
AND ((@SentOnly = 1 AND SenderUserID = @UserID) or (@SentOnly is NULL AND UserID = @UserID) or (@SentOnly = 0 AND UserID = @UserID))
AND m.NotificationTypeID IS NULL AND m.PortalID=@PortalID
GROUP BY ConversationID
)
,Conversations AS
(
SELECT DISTINCT [MessageID], [ConversationID], [Subject], convert(nvarchar(50), [Body]) AS Body,
[To], [From], [ReplyAllAllowed], [SenderUserID],
[CreatedByUserID], [CreatedOnDate],
[LastModifiedByUserID], [LastModifiedOnDate],
(SELECT COUNT(*) FROM {databaseOwner}{objectQualifier}CoreMessaging_MessageAttachments WHERE MessageID IN (SELECT MessageID FROM {databaseOwner}{objectQualifier}CoreMessaging_Messages WHERE ConversationID = m.ConversationID)) AS AttachmentCount,
(SELECT COUNT(*) FROM {databaseOwner}{objectQualifier}CoreMessaging_MessageRecipients WHERE MessageID IN (SELECT MessageID FROM {databaseOwner}{objectQualifier}CoreMessaging_Messages WHERE ConversationID = m.ConversationID) AND UserID = @UserID AND [READ] = 0) AS NewThreadCount,
(SELECT COUNT(*) FROM {databaseOwner}{objectQualifier}CoreMessaging_MessageRecipients WHERE MessageID IN (SELECT MessageID FROM {databaseOwner}{objectQualifier}CoreMessaging_Messages WHERE ConversationID = m.ConversationID) AND UserID = @UserID) AS ThreadCount,
ROW_NUMBER() OVER(ORDER BY
CASE WHEN @SortField = 'CreatedOnDate' AND @SortAscending = 1 THEN [CreatedOnDate] END ASC,
CASE WHEN @SortField = 'CreatedOnDate' AND @SortAscending = 0 THEN [CreatedOnDate] END DESC,
CASE WHEN @SortField = 'From' AND @SortAscending = 1 THEN [From] END ASC,
CASE WHEN @SortField = 'From' AND @SortAscending = 0 THEN [From] END DESC,
CASE WHEN @SortField = 'Subject' AND @SortAscending = 1 THEN [Subject] END ASC,
CASE WHEN @SortField = 'Subject' AND @SortAscending = 0 THEN [Subject] END DESC
) AS RowNumber
FROM {databaseOwner}{objectQualifier}CoreMessaging_Messages AS m
WHERE MessageID IN (SELECT TopMessageID FROM RollUpMessageIDs)
)
, ConversationsCount AS
(SELECT *,
(SELECT RowNumber + 1 FROM Conversations WHERE [MessageID] = @AfterMessageID) afterMessageMin,
(SELECT RowNumber + @NumberOfRecords FROM Conversations WHERE [MessageID] = @AfterMessageID ) afterMessageMax
FROM Conversations)
SELECT * FROM ConversationsCount
WHERE
(@AfterMessageID > 0 AND RowNumber BETWEEN afterMessageMin AND afterMessageMax )
OR (@AfterMessageID = -1 AND RowNumber BETWEEN 1 AND @NumberOfRecords)
END
GO

/* Fix for Journal_ListForGroup */
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}[{objectQualifier}Journal_ListForGroup]') AND type in (N'P', N'PC'))
DROP PROCEDURE {databaseOwner}[{objectQualifier}Journal_ListForGroup]
GO

CREATE PROCEDURE {databaseOwner}[{objectQualifier}Journal_ListForGroup]
@PortalId int,
@ModuleId int,
@CurrentUserId int,
@GroupId int,
@RowIndex int,
@MaxRows int,
@IncludeAllItems int = 0,
@IsDeleted int = 0
AS
DECLARE @EndRow int
SET @EndRow = @RowIndex + @MaxRows;
DECLARE @j TABLE(id int IDENTITY, journalid int, datecreated datetime)
IF EXISTS(SELECT * from {databaseOwner}[{objectQualifier}Journal_TypeFilters] WHERE ModuleId = @ModuleId)
INSERT INTO @j
SELECT j.journalid, jt.datecreated from (
SELECT DISTINCT js.JournalId from {databaseOwner}[{objectQualifier}Journal] as j
INNER JOIN {databaseOwner}[{objectQualifier}Journal_Security] as js ON js.JournalId = j.JournalId
INNER JOIN {databaseOwner}[{objectQualifier}Journal_User_Permissions](@PortalId,@CurrentUserId ,1) as t
ON t.seckey = js.SecurityKey AND (js.SecurityKey = 'R' + CAST(@GroupId as nvarchar(100)) OR js.SecurityKey = 'E')
WHERE j.PortalId = @PortalId
) as j INNER JOIN {databaseOwner}[{objectQualifier}Journal] jt ON jt.JournalId = j.JournalId AND jt.PortalId = @PortalId AND jt.GroupId = @GroupId
INNER JOIN {databaseOwner}[{objectQualifier}Journal_TypeFilters] as jf ON jf.JournalTypeId = jt.JournalTypeId AND jf.ModuleId = @ModuleId
ORDER BY jt.DateCreated DESC, jt.JournalId DESC;
ELSE
INSERT INTO @j
SELECT j.journalid, jt.datecreated from (
SELECT DISTINCT js.JournalId from {databaseOwner}[{objectQualifier}Journal] as j
INNER JOIN {databaseOwner}[{objectQualifier}Journal_Security] as js ON js.JournalId = j.JournalId
INNER JOIN {databaseOwner}[{objectQualifier}Journal_User_Permissions](@PortalId,@CurrentUserId ,1) as t
ON t.seckey = js.SecurityKey AND (js.SecurityKey = 'R' + CAST(@GroupId as nvarchar(100)) OR js.SecurityKey = 'E')
WHERE j.PortalId = @PortalId
) as j INNER JOIN {databaseOwner}[{objectQualifier}Journal] jt ON jt.JournalId = j.JournalId AND jt.PortalId = @PortalId AND jt.GroupId = @GroupId
ORDER BY jt.DateCreated DESC, jt.JournalId DESC;
WITH journalItems AS
(
SELECT j.JournalId,
ROW_NUMBER() OVER (ORDER BY j.JournalId DESC) AS RowNumber
FROM {databaseOwner}[{objectQualifier}Journal] as j INNER JOIN @j as jtmp ON jtmp.JournalId = j.JournalId
WHERE j.PortalId = @PortalId
AND (((@IncludeAllItems = 0) AND (j.IsDeleted = @IsDeleted))
OR (@IncludeAllItems = 1))
)
SELECT j.JournalId, j.JournalTypeId, j.Title, j.Summary, j.UserId, j.DateCreated, j.DateUpdated, j.PortalId,
j.ProfileId, j.GroupId, j.ObjectKey, j.AccessKey,
"JournalOwner" = '<entity><id>' + CAST(r.RoleId as nvarchar(150)) + '</id><name><![CDATA[' + r.RoleName + ']]></name></entity>',
"JournalAuthor" = CASE WHEN ISNULL(a.UserId,-1) >0 THEN '<entity><id>' + CAST(a.UserId as nvarchar(150)) + '</id><name><![CDATA[' + a.DisplayName + ']]></name></entity>' ELSE '' END,
"JournalOwnerId" = ISNULL(j.ProfileId,j.UserId),
jt.Icon, jt.JournalType,
"Profile" = CASE WHEN j.ProfileId > 0 THEN '<entity><id>' + CAST(p.UserID as nvarchar(150)) + '</id><name><![CDATA[' + p.DisplayName + ']]></name><vanity></vanity></entity>' ELSE '' END,
"SimilarCount" = (SELECT COUNT(JournalId) FROM {databaseOwner}{objectQualifier}Journal WHERE ContentItemId = j.ContentItemId AND JournalTypeId = j.JournalTypeId),
jd.JournalXML, j.ContentItemId, j.ItemData, RowNumber, j.IsDeleted, j.CommentsDisabled, j.CommentsHidden
FROM journalItems as ji INNER JOIN
{databaseOwner}[{objectQualifier}Journal] as j ON j.JournalId = ji.JournalId INNER JOIN
{databaseOwner}[{objectQualifier}Journal_Types] as jt ON jt.JournalTypeId = j.JournalTypeId INNER JOIN
{databaseOwner}[{objectQualifier}Roles] as r ON j.GroupId = r.RoleId LEFT OUTER JOIN
{databaseOwner}[{objectQualifier}Journal_Data] as jd on jd.JournalId = j.JournalId LEFT OUTER JOIN
{databaseOwner}[{objectQualifier}Users] AS p ON j.ProfileId = p.UserID LEFT OUTER JOIN
{databaseOwner}[{objectQualifier}Users] AS a ON j.UserId = a.UserID
WHERE ((@IncludeAllItems = 0) AND (RowNumber BETWEEN @RowIndex AND @EndRow AND j.IsDeleted = @IsDeleted))
OR
((@IncludeAllItems = 1) AND (RowNumber BETWEEN @RowIndex AND @EndRow))
ORDER BY RowNumber ASC;
GO




/************************************************************/
/***** SqlDataProvider *****/
/************************************************************/
Expand Down