Data infrastructure work

This commit is contained in:
Scott Nonnenberg 2019-01-14 13:47:19 -08:00
parent 57abb8300f
commit 92c2a0f996
3 changed files with 133 additions and 7 deletions

View file

@ -68,7 +68,10 @@ module.exports = {
getAllConversationIds, getAllConversationIds,
getAllPrivateConversations, getAllPrivateConversations,
getAllGroupsInvolvingId, getAllGroupsInvolvingId,
searchConversations, searchConversations,
searchMessages,
searchMessagesInConversation,
getMessageCount, getMessageCount,
saveMessage, saveMessage,
@ -459,6 +462,69 @@ async function updateToSchemaVersion7(currentVersion, instance) {
console.log('updateToSchemaVersion7: success!'); console.log('updateToSchemaVersion7: success!');
} }
async function updateToSchemaVersion8(currentVersion, instance) {
if (currentVersion >= 8) {
return;
}
console.log('updateToSchemaVersion8: starting...');
await instance.run('BEGIN TRANSACTION;');
// First, we pull a new body field out of the message table's json blob
await instance.run(
`ALTER TABLE messages
ADD COLUMN body TEXT;`
);
await instance.run("UPDATE messages SET body = json_extract(json, '$.body')");
// Then we create our full-text search table and populate it
await instance.run(`
CREATE VIRTUAL TABLE messages_fts
USING fts5(id UNINDEXED, body);
`);
await instance.run(`
INSERT INTO messages_fts(id, body)
SELECT id, body FROM messages;
`);
// Then we set up triggers to keep the full-text search table up to date
await instance.run(`
CREATE TRIGGER messages_on_insert AFTER INSERT ON messages BEGIN
INSERT INTO messages_fts (
id,
body
) VALUES (
new.id,
new.body
);
END;
`);
await instance.run(`
CREATE TRIGGER messages_on_delete AFTER DELETE ON messages BEGIN
DELETE FROM messages_fts WHERE id = old.id;
END;
`);
await instance.run(`
CREATE TRIGGER messages_on_update AFTER UPDATE ON messages BEGIN
DELETE FROM messages_fts WHERE id = old.id;
INSERT INTO messages_fts(
id,
body
) VALUES (
new.id,
new.body
);
END;
`);
// For formatting search results:
// https://sqlite.org/fts5.html#the_highlight_function
// https://sqlite.org/fts5.html#the_snippet_function
await instance.run('PRAGMA schema_version = 8;');
await instance.run('COMMIT TRANSACTION;');
console.log('updateToSchemaVersion8: success!');
}
const SCHEMA_VERSIONS = [ const SCHEMA_VERSIONS = [
updateToSchemaVersion1, updateToSchemaVersion1,
updateToSchemaVersion2, updateToSchemaVersion2,
@ -467,6 +533,7 @@ const SCHEMA_VERSIONS = [
() => null, // version 5 was dropped () => null, // version 5 was dropped
updateToSchemaVersion6, updateToSchemaVersion6,
updateToSchemaVersion7, updateToSchemaVersion7,
updateToSchemaVersion8,
]; ];
async function updateSchema(instance) { async function updateSchema(instance) {
@ -517,7 +584,7 @@ async function initialize({ configDir, key }) {
const promisified = promisify(sqlInstance); const promisified = promisify(sqlInstance);
// promisified.on('trace', async statement => { // promisified.on('trace', async statement => {
// if (!db) { // if (!db || statement.startsWith('--')) {
// console._log(statement); // console._log(statement);
// return; // return;
// } // }
@ -941,9 +1008,11 @@ async function getAllGroupsInvolvingId(id) {
async function searchConversations(query) { async function searchConversations(query) {
const rows = await db.all( const rows = await db.all(
`SELECT json FROM conversations WHERE `SELECT json FROM conversations WHERE
id LIKE $id OR (
name LIKE $name OR id LIKE $id OR
profileName LIKE $profileName name LIKE $name OR
profileName LIKE $profileName
)
ORDER BY id ASC;`, ORDER BY id ASC;`,
{ {
$id: `%${query}%`, $id: `%${query}%`,
@ -955,6 +1024,58 @@ async function searchConversations(query) {
return map(rows, row => jsonToObject(row.json)); return map(rows, row => jsonToObject(row.json));
} }
async function searchMessages(query, { limit } = {}) {
const rows = await db.all(
`SELECT
messages.json,
snippet(messages_fts, -1, '<<left>>', '<<right>>', '...', 15) as snippet
FROM messages_fts
INNER JOIN messages on messages_fts.id = messages.id
WHERE
messages_fts match $query
ORDER BY messages.received_at DESC
LIMIT $limit;`,
{
$query: query,
$limit: limit || 100,
}
);
return map(rows, row => ({
...jsonToObject(row.json),
snippet: row.snippet,
}));
}
async function searchMessagesInConversation(
query,
conversationId,
{ limit } = {}
) {
const rows = await db.all(
`SELECT
messages.json,
snippet(messages_fts, -1, '<<left>>', '<<right>>', '...', 15) as snippet
FROM messages_fts
INNER JOIN messages on messages_fts.id = messages.id
WHERE
messages_fts match $query AND
messages.conversationId = $conversationId
ORDER BY messages.received_at DESC
LIMIT $limit;`,
{
$query: query,
$conversationId: conversationId,
$limit: limit || 100,
}
);
return map(rows, row => ({
...jsonToObject(row.json),
snippet: row.snippet,
}));
}
async function getMessageCount() { async function getMessageCount() {
const row = await db.get('SELECT count(*) from messages;'); const row = await db.get('SELECT count(*) from messages;');
@ -967,6 +1088,7 @@ async function getMessageCount() {
async function saveMessage(data, { forceSave } = {}) { async function saveMessage(data, { forceSave } = {}) {
const { const {
body,
conversationId, conversationId,
// eslint-disable-next-line camelcase // eslint-disable-next-line camelcase
expires_at, expires_at,
@ -991,6 +1113,7 @@ async function saveMessage(data, { forceSave } = {}) {
$id: id, $id: id,
$json: objectToJSON(data), $json: objectToJSON(data),
$body: body,
$conversationId: conversationId, $conversationId: conversationId,
$expirationStartTimestamp: expirationStartTimestamp, $expirationStartTimestamp: expirationStartTimestamp,
$expires_at: expires_at, $expires_at: expires_at,
@ -1011,6 +1134,7 @@ async function saveMessage(data, { forceSave } = {}) {
await db.run( await db.run(
`UPDATE messages SET `UPDATE messages SET
json = $json, json = $json,
body = $body,
conversationId = $conversationId, conversationId = $conversationId,
expirationStartTimestamp = $expirationStartTimestamp, expirationStartTimestamp = $expirationStartTimestamp,
expires_at = $expires_at, expires_at = $expires_at,
@ -1043,6 +1167,7 @@ async function saveMessage(data, { forceSave } = {}) {
id, id,
json, json,
body,
conversationId, conversationId,
expirationStartTimestamp, expirationStartTimestamp,
expires_at, expires_at,
@ -1061,6 +1186,7 @@ async function saveMessage(data, { forceSave } = {}) {
$id, $id,
$json, $json,
$body,
$conversationId, $conversationId,
$expirationStartTimestamp, $expirationStartTimestamp,
$expires_at, $expires_at,

View file

@ -41,7 +41,7 @@
"styleguide": "styleguidist server" "styleguide": "styleguidist server"
}, },
"dependencies": { "dependencies": {
"@journeyapps/sqlcipher": "https://github.com/scottnonnenberg-signal/node-sqlcipher.git#ed4f4d179ac010c6347b291cbd4c2ebe5c773741", "@journeyapps/sqlcipher": "https://github.com/scottnonnenberg-signal/node-sqlcipher.git#36149a4b03ccf11ec18b9205e1bfd9056015cf07",
"@sindresorhus/is": "0.8.0", "@sindresorhus/is": "0.8.0",
"backbone": "1.3.3", "backbone": "1.3.3",
"blob-util": "1.3.0", "blob-util": "1.3.0",

View file

@ -22,9 +22,9 @@
"7zip-bin-mac" "~1.0.1" "7zip-bin-mac" "~1.0.1"
"7zip-bin-win" "~2.2.0" "7zip-bin-win" "~2.2.0"
"@journeyapps/sqlcipher@https://github.com/scottnonnenberg-signal/node-sqlcipher.git#ed4f4d179ac010c6347b291cbd4c2ebe5c773741": "@journeyapps/sqlcipher@https://github.com/scottnonnenberg-signal/node-sqlcipher.git#36149a4b03ccf11ec18b9205e1bfd9056015cf07":
version "3.2.1" version "3.2.1"
resolved "https://github.com/scottnonnenberg-signal/node-sqlcipher.git#ed4f4d179ac010c6347b291cbd4c2ebe5c773741" resolved "https://github.com/scottnonnenberg-signal/node-sqlcipher.git#36149a4b03ccf11ec18b9205e1bfd9056015cf07"
dependencies: dependencies:
nan "^2.10.0" nan "^2.10.0"
node-pre-gyp "^0.10.0" node-pre-gyp "^0.10.0"