New SQL indices and query tweaks to eliminate table scans

Also: New logging on client side to track performance of db queries
This commit is contained in:
Scott Nonnenberg 2018-08-08 18:32:10 -07:00
parent 85ab4e567f
commit c88df69094
2 changed files with 61 additions and 11 deletions

View file

@ -240,8 +240,41 @@ async function updateToSchemaVersion2(currentVersion, instance) {
console.log('updateToSchemaVersion2: success!'); console.log('updateToSchemaVersion2: success!');
} }
// const SCHEMA_VERSIONS = [updateToSchemaVersion1]; async function updateToSchemaVersion3(currentVersion, instance) {
const SCHEMA_VERSIONS = [updateToSchemaVersion1, updateToSchemaVersion2]; if (currentVersion >= 3) {
return;
}
console.log('updateToSchemaVersion3: starting...');
await instance.run('BEGIN TRANSACTION;');
await instance.run('DROP INDEX messages_expiring;');
await instance.run('DROP INDEX messages_unread;');
await instance.run(`CREATE INDEX messages_without_timer ON messages (
expireTimer,
expires_at,
type
) WHERE expires_at IS NULL AND expireTimer IS NOT NULL;`);
await instance.run(`CREATE INDEX messages_unread ON messages (
conversationId,
unread
) WHERE unread IS NOT NULL;`);
await instance.run('ANALYZE;');
await instance.run('PRAGMA schema_version = 3;');
await instance.run('COMMIT TRANSACTION;');
console.log('updateToSchemaVersion3: success!');
}
const SCHEMA_VERSIONS = [
updateToSchemaVersion1,
updateToSchemaVersion2,
updateToSchemaVersion3,
];
async function updateSchema(instance) { async function updateSchema(instance) {
const sqliteVersion = await getSQLiteVersion(instance); const sqliteVersion = await getSQLiteVersion(instance);
@ -286,7 +319,14 @@ async function initialize({ configDir, key }) {
const sqlInstance = await openDatabase(filePath); const sqlInstance = await openDatabase(filePath);
const promisified = promisify(sqlInstance); const promisified = promisify(sqlInstance);
// promisified.on('trace', statement => console._log(statement)); // promisified.on('trace', async statement => {
// if (!db) {
// console._log(statement);
// return;
// }
// const data = await db.get(`EXPLAIN QUERY PLAN ${statement}`);
// console._log(`EXPLAIN QUERY PLAN ${statement}\n`, data && data.detail);
// });
await setupSQLCipher(promisified, { key }); await setupSQLCipher(promisified, { key });
await updateSchema(promisified); await updateSchema(promisified);
@ -507,12 +547,12 @@ async function getMessageBySender({ source, sourceDevice, sent_at }) {
async function getUnreadByConversation(conversationId) { async function getUnreadByConversation(conversationId) {
const rows = await db.all( const rows = await db.all(
`SELECT json FROM messages WHERE `SELECT json FROM messages WHERE
conversationId = $conversationId AND unread = $unread AND
unread = $unread conversationId = $conversationId
ORDER BY received_at DESC;`, ORDER BY received_at DESC;`,
{ {
$conversationId: conversationId,
$unread: 1, $unread: 1,
$conversationId: conversationId,
} }
); );
@ -588,9 +628,9 @@ async function getOutgoingWithoutExpiresAt() {
const rows = await db.all(` const rows = await db.all(`
SELECT json FROM messages SELECT json FROM messages
WHERE WHERE
(expireTimer IS NOT NULL AND expireTimer IS NOT 0) AND expireTimer > 0 AND
type IS 'outgoing' AND expires_at IS NULL AND
(expirationStartTimestamp IS NULL OR expires_at IS NULL) type IS 'outgoing'
ORDER BY expires_at ASC; ORDER BY expires_at ASC;
`); `);
@ -604,7 +644,7 @@ async function getOutgoingWithoutExpiresAt() {
async function getNextExpiringMessage() { async function getNextExpiringMessage() {
const rows = await db.all(` const rows = await db.all(`
SELECT json FROM messages SELECT json FROM messages
WHERE expires_at IS NOT NULL WHERE expires_at > 0
ORDER BY expires_at ASC ORDER BY expires_at ASC
LIMIT 1; LIMIT 1;
`); `);
@ -734,7 +774,7 @@ async function removeAll() {
async function getMessagesNeedingUpgrade(limit, { maxVersion }) { async function getMessagesNeedingUpgrade(limit, { maxVersion }) {
const rows = await db.all( const rows = await db.all(
`SELECT json FROM messages `SELECT json FROM messages
WHERE schemaVersion IS NOT $maxVersion WHERE schemaVersion IS NULL OR schemaVersion < $maxVersion
LIMIT $limit;`, LIMIT $limit;`,
{ {
$maxVersion: maxVersion, $maxVersion: maxVersion,

View file

@ -112,6 +112,7 @@ function _makeJob(fnName) {
_jobs[id] = { _jobs[id] = {
fnName, fnName,
start: Date.now(),
}; };
return id; return id;
@ -119,16 +120,25 @@ function _makeJob(fnName) {
function _updateJob(id, data) { function _updateJob(id, data) {
const { resolve, reject } = data; const { resolve, reject } = data;
const { fnName, start } = _jobs[id];
_jobs[id] = { _jobs[id] = {
..._jobs[id], ..._jobs[id],
...data, ...data,
resolve: value => { resolve: value => {
_removeJob(id); _removeJob(id);
const end = Date.now();
window.log.info(
`SQL channel job ${id} (${fnName}) succeeded in ${end - start}ms`
);
return resolve(value); return resolve(value);
}, },
reject: error => { reject: error => {
_removeJob(id); _removeJob(id);
const end = Date.now();
window.log.info(
`SQL channel job ${id} (${fnName}) failed in ${end - start}ms`
);
return reject(error); return reject(error);
}, },
}; };