messages table: introduce new computed isStory field for index usage
This commit is contained in:
parent
e57ca66fd0
commit
42cb570029
4 changed files with 120 additions and 8 deletions
|
@ -2333,7 +2333,7 @@ async function getOlderMessagesByConversation(
|
|||
SELECT json FROM messages WHERE
|
||||
conversationId = $conversationId AND
|
||||
($messageId IS NULL OR id IS NOT $messageId) AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId AND
|
||||
(
|
||||
(received_at = $received_at AND sent_at < $sent_at) OR
|
||||
|
@ -2415,7 +2415,7 @@ async function getNewerMessagesByConversation(
|
|||
`
|
||||
SELECT json FROM messages WHERE
|
||||
conversationId = $conversationId AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId AND
|
||||
(
|
||||
(received_at = $received_at AND sent_at > $sent_at) OR
|
||||
|
@ -2445,7 +2445,7 @@ function getOldestMessageForConversation(
|
|||
`
|
||||
SELECT * FROM messages WHERE
|
||||
conversationId = $conversationId AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId
|
||||
ORDER BY received_at ASC, sent_at ASC
|
||||
LIMIT 1;
|
||||
|
@ -2472,7 +2472,7 @@ function getNewestMessageForConversation(
|
|||
`
|
||||
SELECT * FROM messages WHERE
|
||||
conversationId = $conversationId AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId
|
||||
ORDER BY received_at DESC, sent_at DESC
|
||||
LIMIT 1;
|
||||
|
@ -2632,7 +2632,7 @@ function getOldestUnreadMessageForConversation(
|
|||
SELECT * FROM messages WHERE
|
||||
conversationId = $conversationId AND
|
||||
readStatus = ${ReadStatus.Unread} AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId
|
||||
ORDER BY received_at ASC, sent_at ASC
|
||||
LIMIT 1;
|
||||
|
@ -2663,7 +2663,7 @@ async function getTotalUnreadForConversation(
|
|||
WHERE
|
||||
conversationId = $conversationId AND
|
||||
readStatus = ${ReadStatus.Unread} AND
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS $storyId;
|
||||
`
|
||||
)
|
||||
|
@ -4163,7 +4163,7 @@ async function getMessagesWithVisualMediaAttachments(
|
|||
.prepare<Query>(
|
||||
`
|
||||
SELECT json FROM messages WHERE
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS NULL AND
|
||||
conversationId = $conversationId AND
|
||||
hasVisualMediaAttachments = 1
|
||||
|
@ -4188,7 +4188,7 @@ async function getMessagesWithFileAttachments(
|
|||
.prepare<Query>(
|
||||
`
|
||||
SELECT json FROM messages WHERE
|
||||
type IS NOT 'story' AND
|
||||
isStory IS 0 AND
|
||||
storyId IS NULL AND
|
||||
conversationId = $conversationId AND
|
||||
hasFileAttachments = 1
|
||||
|
|
40
ts/sql/migrations/46-optimize-stories.ts
Normal file
40
ts/sql/migrations/46-optimize-stories.ts
Normal file
|
@ -0,0 +1,40 @@
|
|||
// Copyright 2021 Signal Messenger, LLC
|
||||
// SPDX-License-Identifier: AGPL-3.0-only
|
||||
|
||||
import type { Database } from 'better-sqlite3';
|
||||
|
||||
import type { LoggerType } from '../../types/Logging';
|
||||
|
||||
export default function updateToSchemaVersion46(
|
||||
currentVersion: number,
|
||||
db: Database,
|
||||
logger: LoggerType
|
||||
): void {
|
||||
if (currentVersion >= 46) {
|
||||
return;
|
||||
}
|
||||
|
||||
db.transaction(() => {
|
||||
db.exec(
|
||||
`
|
||||
--- Add column to messages table
|
||||
|
||||
ALTER TABLE messages
|
||||
ADD COLUMN
|
||||
isStory INTEGER
|
||||
GENERATED ALWAYS
|
||||
AS (type = 'story');
|
||||
|
||||
--- Update important message indices
|
||||
|
||||
DROP INDEX messages_conversation;
|
||||
CREATE INDEX messages_conversation ON messages
|
||||
(conversationId, isStory, storyId, received_at, sent_at);
|
||||
`
|
||||
);
|
||||
|
||||
db.pragma('user_version = 46');
|
||||
})();
|
||||
|
||||
logger.info('updateToSchemaVersion46: success!');
|
||||
}
|
|
@ -21,6 +21,7 @@ import updateToSchemaVersion42 from './42-stale-reactions';
|
|||
import updateToSchemaVersion43 from './43-gv2-uuid';
|
||||
import updateToSchemaVersion44 from './44-badges';
|
||||
import updateToSchemaVersion45 from './45-stories';
|
||||
import updateToSchemaVersion46 from './46-optimize-stories';
|
||||
|
||||
function updateToSchemaVersion1(
|
||||
currentVersion: number,
|
||||
|
@ -1905,6 +1906,7 @@ export const SCHEMA_VERSIONS = [
|
|||
updateToSchemaVersion43,
|
||||
updateToSchemaVersion44,
|
||||
updateToSchemaVersion45,
|
||||
updateToSchemaVersion46,
|
||||
];
|
||||
|
||||
export function updateSchema(db: Database, logger: LoggerType): void {
|
||||
|
|
|
@ -909,4 +909,74 @@ describe('SQL migrations test', () => {
|
|||
assert.sameDeepMembers(members, [UUID_1, UUID_2]);
|
||||
});
|
||||
});
|
||||
|
||||
describe('updateToSchemaVersion46', () => {
|
||||
it('creates new auto-generated isStory field', () => {
|
||||
const STORY_ID_1 = generateGuid();
|
||||
const MESSAGE_ID_1 = generateGuid();
|
||||
const MESSAGE_ID_2 = generateGuid();
|
||||
const CONVERSATION_ID = generateGuid();
|
||||
|
||||
updateToVersion(46);
|
||||
|
||||
db.exec(
|
||||
`
|
||||
INSERT INTO messages
|
||||
(id, storyId, conversationId, type, body)
|
||||
VALUES
|
||||
('${MESSAGE_ID_1}', '${STORY_ID_1}', '${CONVERSATION_ID}', 'story', 'story 1'),
|
||||
('${MESSAGE_ID_2}', null, '${CONVERSATION_ID}', 'outgoing', 'reply to story 1');
|
||||
`
|
||||
);
|
||||
|
||||
assert.strictEqual(
|
||||
db.prepare('SELECT COUNT(*) FROM messages;').pluck().get(),
|
||||
2
|
||||
);
|
||||
assert.strictEqual(
|
||||
db
|
||||
.prepare('SELECT COUNT(*) FROM messages WHERE isStory IS 0;')
|
||||
.pluck()
|
||||
.get(),
|
||||
1
|
||||
);
|
||||
assert.strictEqual(
|
||||
db
|
||||
.prepare('SELECT COUNT(*) FROM messages WHERE isStory IS 1;')
|
||||
.pluck()
|
||||
.get(),
|
||||
1
|
||||
);
|
||||
});
|
||||
|
||||
it('ensures that index is used for getOlderMessagesByConversation', () => {
|
||||
updateToVersion(46);
|
||||
|
||||
const { detail } = db
|
||||
.prepare(
|
||||
`
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT json FROM messages WHERE
|
||||
conversationId = 'd8b05bb1-36b3-4478-841b-600af62321eb' AND
|
||||
(NULL IS NULL OR id IS NOT NULL) AND
|
||||
isStory IS 0 AND
|
||||
storyId IS NULL AND
|
||||
(
|
||||
(received_at = 17976931348623157 AND sent_at < NULL) OR
|
||||
received_at < 17976931348623157
|
||||
)
|
||||
ORDER BY received_at DESC, sent_at DESC
|
||||
LIMIT 10;
|
||||
`
|
||||
)
|
||||
.get();
|
||||
|
||||
assert.notInclude(detail, 'B-TREE');
|
||||
assert.notInclude(detail, 'SCAN');
|
||||
assert.include(
|
||||
detail,
|
||||
'SEARCH messages USING INDEX messages_conversation (conversationId=? AND isStory=? AND storyId=? AND received_at<?)'
|
||||
);
|
||||
});
|
||||
});
|
||||
});
|
||||
|
|
Loading…
Add table
Reference in a new issue