Short-circuit storyId predicate to optimize query
This commit is contained in:
parent
bddd55d574
commit
35b5087dc0
4 changed files with 130 additions and 10 deletions
|
@ -8,7 +8,11 @@ import { v4 as generateGuid } from 'uuid';
|
|||
|
||||
import { SCHEMA_VERSIONS } from '../sql/migrations';
|
||||
import { consoleLogger } from '../util/consoleLogger';
|
||||
import { getJobsInQueueSync, insertJobSync } from '../sql/Server';
|
||||
import {
|
||||
getJobsInQueueSync,
|
||||
insertJobSync,
|
||||
_storyIdPredicate,
|
||||
} from '../sql/Server';
|
||||
|
||||
const OUR_UUID = generateGuid();
|
||||
|
||||
|
@ -1600,4 +1604,70 @@ describe('SQL migrations test', () => {
|
|||
]);
|
||||
});
|
||||
});
|
||||
|
||||
describe('updateToSchemaVersion52', () => {
|
||||
const queries = [
|
||||
{
|
||||
query: `
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT * FROM messages WHERE
|
||||
conversationId = 'conversation' AND
|
||||
readStatus = 'something' AND
|
||||
isStory IS 0 AND
|
||||
:story_id_predicate:
|
||||
ORDER BY received_at ASC, sent_at ASC
|
||||
LIMIT 1;
|
||||
`,
|
||||
index: 'messages_unread',
|
||||
},
|
||||
{
|
||||
query: `
|
||||
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
|
||||
:story_id_predicate: AND
|
||||
(
|
||||
(received_at = 17976931348623157 AND sent_at < NULL) OR
|
||||
received_at < 17976931348623157
|
||||
)
|
||||
ORDER BY received_at DESC, sent_at DESC
|
||||
LIMIT 10;
|
||||
`,
|
||||
index: 'messages_conversation',
|
||||
},
|
||||
];
|
||||
|
||||
function insertPredicate(
|
||||
query: string,
|
||||
storyId: string | undefined
|
||||
): string {
|
||||
return query.replaceAll(
|
||||
':story_id_predicate:',
|
||||
_storyIdPredicate(storyId)
|
||||
);
|
||||
}
|
||||
|
||||
it('produces optimizable queries for present and absent storyId', () => {
|
||||
updateToVersion(52);
|
||||
|
||||
for (const storyId of ['123', undefined]) {
|
||||
for (const { query, index } of queries) {
|
||||
const details = db
|
||||
.prepare(insertPredicate(query, storyId))
|
||||
.all({ storyId })
|
||||
.map(({ detail }) => detail)
|
||||
.join('\n');
|
||||
|
||||
const postfixedIndex = index + (storyId ? '' : '_no_story_id');
|
||||
|
||||
// Intentional trailing whitespace
|
||||
assert.include(details, `USING INDEX ${postfixedIndex} `);
|
||||
assert.notInclude(details, 'TEMP B-TREE');
|
||||
assert.notInclude(details, 'SCAN');
|
||||
}
|
||||
}
|
||||
});
|
||||
});
|
||||
});
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue