-
Notifications
You must be signed in to change notification settings - Fork 6
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
fix: extremely slow paginated conversation list query [WPB-11808] (#3098
) * fix: extremely slow paginated conversation list query [WPB-11808] * fix name * handle case of moving messages to other conversation * add tests
- Loading branch information
Showing
9 changed files
with
515 additions
and
43 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
111 changes: 111 additions & 0 deletions
111
persistence/src/commonMain/db_user/com/wire/kalium/persistence/LastMessage.sq
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,111 @@ | ||
import com.wire.kalium.persistence.dao.QualifiedIDEntity; | ||
import com.wire.kalium.persistence.dao.conversation.ConversationEntity; | ||
import com.wire.kalium.persistence.dao.message.MessageEntity.ContentType; | ||
import com.wire.kalium.persistence.dao.message.MessageEntity.FederationType; | ||
import com.wire.kalium.persistence.dao.message.MessageEntity.LegalHoldType; | ||
import com.wire.kalium.persistence.dao.message.MessageEntity.MemberChangeType; | ||
import com.wire.kalium.persistence.dao.message.MessageEntity; | ||
import com.wire.kalium.persistence.dao.message.RecipientFailureTypeEntity; | ||
import kotlin.Boolean; | ||
import kotlin.Float; | ||
import kotlin.Int; | ||
import kotlin.String; | ||
import kotlin.collections.List; | ||
import kotlinx.datetime.Instant; | ||
|
||
CREATE TABLE LastMessage ( | ||
conversation_id TEXT AS QualifiedIDEntity, | ||
message_id TEXT, | ||
creation_date INTEGER AS Instant, | ||
|
||
FOREIGN KEY (conversation_id) REFERENCES Conversation(qualified_id) ON DELETE CASCADE ON UPDATE SET NULL, -- there is a trigger to handle null values | ||
FOREIGN KEY (message_id, conversation_id) REFERENCES Message(id, conversation_id) ON DELETE CASCADE ON UPDATE SET NULL, -- there is a trigger to handle null values | ||
PRIMARY KEY (conversation_id) | ||
); | ||
|
||
-- update last message when newly inserted message is newer than the current last message | ||
CREATE TRIGGER updateLastMessageAfterInsertingNewMessage | ||
AFTER INSERT ON Message | ||
WHEN | ||
new.visibility IN ('VISIBLE', 'DELETED') | ||
AND new.content_type IN ('TEXT', 'ASSET', 'KNOCK', 'MISSED_CALL', 'CONVERSATION_RENAMED', 'MEMBER_CHANGE', 'COMPOSITE', 'CONVERSATION_DEGRADED_MLS', 'CONVERSATION_DEGRADED_PROTEUS', 'CONVERSATION_VERIFIED_MLS', 'CONVERSATION_VERIFIED_PROTEUS', 'LOCATION') | ||
BEGIN | ||
INSERT INTO LastMessage(conversation_id, message_id, creation_date) | ||
VALUES (new.conversation_id, new.id, new.creation_date) | ||
ON CONFLICT(conversation_id) | ||
DO UPDATE SET | ||
message_id = excluded.message_id, | ||
creation_date = excluded.creation_date | ||
WHERE | ||
excluded.creation_date > LastMessage.creation_date; | ||
END; | ||
|
||
-- update last message after deleting the current last message by finding new last message for the conversation | ||
CREATE TRIGGER updateLastMessageAfterDeletingLastMessage | ||
AFTER DELETE ON LastMessage | ||
BEGIN | ||
INSERT INTO LastMessage(conversation_id, message_id, creation_date) | ||
SELECT conversation_id, id, creation_date | ||
FROM Message | ||
WHERE | ||
old.conversation_id = Message.conversation_id | ||
AND Message.visibility IN ('VISIBLE', 'DELETED') | ||
AND Message.content_type IN ('TEXT', 'ASSET', 'KNOCK', 'MISSED_CALL', 'CONVERSATION_RENAMED', 'MEMBER_CHANGE', 'COMPOSITE', 'CONVERSATION_DEGRADED_MLS', 'CONVERSATION_DEGRADED_PROTEUS', 'CONVERSATION_VERIFIED_MLS', 'CONVERSATION_VERIFIED_PROTEUS', 'LOCATION') | ||
ORDER BY creation_date DESC | ||
LIMIT 1 | ||
ON CONFLICT(conversation_id) | ||
DO UPDATE SET | ||
message_id = excluded.message_id, | ||
creation_date = excluded.creation_date | ||
WHERE | ||
excluded.creation_date > LastMessage.creation_date; | ||
END; | ||
|
||
-- update last message after a message got updated and now this one should be the new last message | ||
-- or if the current last message shouldn't be the last message anymore because of the visibility update for instance | ||
CREATE TRIGGER updateLastMessageAfterUpdatingMessage | ||
AFTER UPDATE OF id, conversation_id, visibility, content_type, creation_date ON Message | ||
WHEN | ||
new.creation_date >= (SELECT creation_date FROM LastMessage WHERE conversation_id = new.conversation_id LIMIT 1) | ||
BEGIN | ||
INSERT INTO LastMessage(conversation_id, message_id, creation_date) | ||
SELECT conversation_id, id, creation_date | ||
FROM Message | ||
WHERE | ||
new.conversation_id = Message.conversation_id | ||
AND Message.visibility IN ('VISIBLE', 'DELETED') | ||
AND Message.content_type IN ('TEXT', 'ASSET', 'KNOCK', 'MISSED_CALL', 'CONVERSATION_RENAMED', 'MEMBER_CHANGE', 'COMPOSITE', 'CONVERSATION_DEGRADED_MLS', 'CONVERSATION_DEGRADED_PROTEUS', 'CONVERSATION_VERIFIED_MLS', 'CONVERSATION_VERIFIED_PROTEUS', 'LOCATION') | ||
ORDER BY creation_date DESC | ||
LIMIT 1 | ||
ON CONFLICT(conversation_id) | ||
DO UPDATE SET | ||
message_id = excluded.message_id, | ||
creation_date = excluded.creation_date | ||
WHERE | ||
excluded.creation_date > LastMessage.creation_date; | ||
END; | ||
|
||
-- update last message after there was a foreign key updated to null by finding new last message for that conversation | ||
-- this happens when last message is moved to another conversation or id of last message is changed | ||
CREATE TRIGGER updateLastMessageAfterForeignKeyUpdatedToNull | ||
AFTER UPDATE OF conversation_id ON LastMessage | ||
WHEN | ||
new.conversation_id IS NULL | ||
BEGIN | ||
INSERT INTO LastMessage(conversation_id, message_id, creation_date) | ||
SELECT conversation_id, id, creation_date | ||
FROM Message | ||
WHERE | ||
old.conversation_id = Message.conversation_id | ||
AND Message.visibility IN ('VISIBLE', 'DELETED') | ||
AND Message.content_type IN ('TEXT', 'ASSET', 'KNOCK', 'MISSED_CALL', 'CONVERSATION_RENAMED', 'MEMBER_CHANGE', 'COMPOSITE', 'CONVERSATION_DEGRADED_MLS', 'CONVERSATION_DEGRADED_PROTEUS', 'CONVERSATION_VERIFIED_MLS', 'CONVERSATION_VERIFIED_PROTEUS', 'LOCATION') | ||
ORDER BY creation_date DESC | ||
LIMIT 1 | ||
ON CONFLICT(conversation_id) | ||
DO UPDATE SET | ||
message_id = excluded.message_id, | ||
creation_date = excluded.creation_date | ||
WHERE | ||
excluded.creation_date > LastMessage.creation_date; | ||
DELETE FROM LastMessage WHERE conversation_id IS NULL; | ||
END; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.