mirror of
				https://github.com/zadam/trilium.git
				synced 2025-10-31 10:26:08 +01:00 
			
		
		
		
	Compare commits
	
		
			16 Commits
		
	
	
		
			copilot/fi
			...
			feat/rice-
		
	
	| Author | SHA1 | Date | |
|---|---|---|---|
|  | 10988095c2 | ||
|  | 253da139de | ||
|  | d992a5e4a2 | ||
|  | 58c225237c | ||
|  | d074841885 | ||
|  | 06b2d71b27 | ||
|  | 0afb8a11c8 | ||
|  | f529ddc601 | ||
|  | 8572f82e0a | ||
|  | b09a2c386d | ||
|  | 7c5553bd4b | ||
|  | 37d0136c50 | ||
|  | 5b79e0d71e | ||
|  | 053f722cb8 | ||
|  | 21aaec2c38 | ||
|  | 1db4971da6 | 
| @@ -146,9 +146,228 @@ CREATE INDEX IDX_notes_blobId on notes (blobId); | |||||||
| CREATE INDEX IDX_revisions_blobId on revisions (blobId); | CREATE INDEX IDX_revisions_blobId on revisions (blobId); | ||||||
| CREATE INDEX IDX_attachments_blobId on attachments (blobId); | CREATE INDEX IDX_attachments_blobId on attachments (blobId); | ||||||
|  |  | ||||||
|  | -- Strategic Performance Indexes from migration 234 | ||||||
|  | -- NOTES TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_notes_search_composite  | ||||||
|  | ON notes (isDeleted, type, mime, dateModified DESC); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_notes_metadata_covering  | ||||||
|  | ON notes (noteId, isDeleted, type, mime, title, dateModified, isProtected); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_notes_protected_deleted  | ||||||
|  | ON notes (isProtected, isDeleted)  | ||||||
|  | WHERE isProtected = 1; | ||||||
|  |  | ||||||
|  | -- BRANCHES TABLE INDEXES   | ||||||
|  | CREATE INDEX IDX_branches_tree_traversal  | ||||||
|  | ON branches (parentNoteId, isDeleted, notePosition); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_branches_covering  | ||||||
|  | ON branches (noteId, parentNoteId, isDeleted, notePosition, prefix); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_branches_note_parents  | ||||||
|  | ON branches (noteId, isDeleted)  | ||||||
|  | WHERE isDeleted = 0; | ||||||
|  |  | ||||||
|  | -- ATTRIBUTES TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_attributes_search_composite  | ||||||
|  | ON attributes (name, value, isDeleted); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_attributes_covering  | ||||||
|  | ON attributes (noteId, name, value, type, isDeleted, position); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_attributes_inheritable  | ||||||
|  | ON attributes (isInheritable, isDeleted)  | ||||||
|  | WHERE isInheritable = 1 AND isDeleted = 0; | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_attributes_labels  | ||||||
|  | ON attributes (type, name, value)  | ||||||
|  | WHERE type = 'label' AND isDeleted = 0; | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_attributes_relations  | ||||||
|  | ON attributes (type, name, value)  | ||||||
|  | WHERE type = 'relation' AND isDeleted = 0; | ||||||
|  |  | ||||||
|  | -- BLOBS TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_blobs_content_size  | ||||||
|  | ON blobs (blobId, LENGTH(content)); | ||||||
|  |  | ||||||
|  | -- ATTACHMENTS TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_attachments_composite  | ||||||
|  | ON attachments (ownerId, role, isDeleted, position); | ||||||
|  |  | ||||||
|  | -- REVISIONS TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_revisions_note_date  | ||||||
|  | ON revisions (noteId, utcDateCreated DESC); | ||||||
|  |  | ||||||
|  | -- ENTITY_CHANGES TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_entity_changes_sync  | ||||||
|  | ON entity_changes (isSynced, utcDateChanged); | ||||||
|  |  | ||||||
|  | CREATE INDEX IDX_entity_changes_component  | ||||||
|  | ON entity_changes (componentId, utcDateChanged DESC); | ||||||
|  |  | ||||||
|  | -- RECENT_NOTES TABLE INDEXES | ||||||
|  | CREATE INDEX IDX_recent_notes_date  | ||||||
|  | ON recent_notes (utcDateCreated DESC); | ||||||
|  |  | ||||||
|  |  | ||||||
| CREATE TABLE IF NOT EXISTS sessions ( | CREATE TABLE IF NOT EXISTS sessions ( | ||||||
|     id TEXT PRIMARY KEY, |     id TEXT PRIMARY KEY, | ||||||
|     data TEXT, |     data TEXT, | ||||||
|     expires INTEGER |     expires INTEGER | ||||||
| ); | ); | ||||||
|  |  | ||||||
|  | -- FTS5 Full-Text Search Support | ||||||
|  | -- Create FTS5 virtual table with trigram tokenizer | ||||||
|  | -- Trigram tokenizer provides language-agnostic substring matching: | ||||||
|  | -- 1. Fast substring matching (50-100x speedup for LIKE queries without wildcards) | ||||||
|  | -- 2. Case-insensitive search without custom collation | ||||||
|  | -- 3. No language-specific stemming assumptions (works for all languages) | ||||||
|  | -- 4. Boolean operators (AND, OR, NOT) and phrase matching with quotes | ||||||
|  | -- | ||||||
|  | -- IMPORTANT: Trigram requires minimum 3-character tokens for matching | ||||||
|  | -- detail='none' reduces index size by ~50% while maintaining MATCH/rank performance | ||||||
|  | -- (loses position info for highlight() function, but snippet() still works) | ||||||
|  | CREATE VIRTUAL TABLE notes_fts USING fts5( | ||||||
|  |     noteId UNINDEXED, | ||||||
|  |     title, | ||||||
|  |     content, | ||||||
|  |     tokenize = 'trigram', | ||||||
|  |     detail = 'none' | ||||||
|  | ); | ||||||
|  |  | ||||||
|  | -- Triggers to keep FTS table synchronized with notes | ||||||
|  | -- IMPORTANT: These triggers must handle all SQL operations including: | ||||||
|  | -- - Regular INSERT/UPDATE/DELETE | ||||||
|  | -- - INSERT OR REPLACE | ||||||
|  | -- - INSERT ... ON CONFLICT ... DO UPDATE (upsert) | ||||||
|  | -- - Cases where notes are created before blobs (import scenarios) | ||||||
|  |  | ||||||
|  | -- Trigger for INSERT operations on notes | ||||||
|  | -- Handles: INSERT, INSERT OR REPLACE, INSERT OR IGNORE, and the INSERT part of upsert | ||||||
|  | CREATE TRIGGER notes_fts_insert  | ||||||
|  | AFTER INSERT ON notes | ||||||
|  | WHEN NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap')  | ||||||
|  |     AND NEW.isDeleted = 0 | ||||||
|  |     AND NEW.isProtected = 0 | ||||||
|  | BEGIN | ||||||
|  |     -- First delete any existing FTS entry (in case of INSERT OR REPLACE) | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |      | ||||||
|  |     -- Then insert the new entry, using LEFT JOIN to handle missing blobs | ||||||
|  |     INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |     SELECT  | ||||||
|  |         NEW.noteId, | ||||||
|  |         NEW.title, | ||||||
|  |         COALESCE(b.content, '')  -- Use empty string if blob doesn't exist yet | ||||||
|  |     FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |     LEFT JOIN blobs b ON b.blobId = NEW.blobId; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for UPDATE operations on notes table | ||||||
|  | -- Handles: Regular UPDATE and the UPDATE part of upsert (ON CONFLICT DO UPDATE) | ||||||
|  | -- Fires for ANY update to searchable notes to ensure FTS stays in sync | ||||||
|  | CREATE TRIGGER notes_fts_update  | ||||||
|  | AFTER UPDATE ON notes | ||||||
|  | WHEN NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |     -- Fire on any change, not just specific columns, to handle all upsert scenarios | ||||||
|  | BEGIN | ||||||
|  |     -- Always delete the old entry | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |      | ||||||
|  |     -- Insert new entry if note is not deleted and not protected | ||||||
|  |     INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |     SELECT  | ||||||
|  |         NEW.noteId, | ||||||
|  |         NEW.title, | ||||||
|  |         COALESCE(b.content, '')  -- Use empty string if blob doesn't exist yet | ||||||
|  |     FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |     LEFT JOIN blobs b ON b.blobId = NEW.blobId | ||||||
|  |     WHERE NEW.isDeleted = 0 | ||||||
|  |         AND NEW.isProtected = 0; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for UPDATE operations on blobs | ||||||
|  | -- Handles: Regular UPDATE and the UPDATE part of upsert (ON CONFLICT DO UPDATE) | ||||||
|  | -- IMPORTANT: Uses INSERT OR REPLACE for efficiency with deduplicated blobs | ||||||
|  | CREATE TRIGGER notes_fts_blob_update  | ||||||
|  | AFTER UPDATE ON blobs | ||||||
|  | BEGIN | ||||||
|  |     -- Use INSERT OR REPLACE for atomic update of all notes sharing this blob | ||||||
|  |     -- This is more efficient than DELETE + INSERT when many notes share the same blob | ||||||
|  |     INSERT OR REPLACE INTO notes_fts (noteId, title, content) | ||||||
|  |     SELECT  | ||||||
|  |         n.noteId, | ||||||
|  |         n.title, | ||||||
|  |         NEW.content | ||||||
|  |     FROM notes n | ||||||
|  |     WHERE n.blobId = NEW.blobId | ||||||
|  |         AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |         AND n.isDeleted = 0 | ||||||
|  |         AND n.isProtected = 0; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for DELETE operations | ||||||
|  | CREATE TRIGGER notes_fts_delete  | ||||||
|  | AFTER DELETE ON notes | ||||||
|  | BEGIN | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = OLD.noteId; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for soft delete (isDeleted = 1) | ||||||
|  | CREATE TRIGGER notes_fts_soft_delete  | ||||||
|  | AFTER UPDATE ON notes | ||||||
|  | WHEN OLD.isDeleted = 0 AND NEW.isDeleted = 1 | ||||||
|  | BEGIN | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for notes becoming protected | ||||||
|  | -- Remove from FTS when a note becomes protected | ||||||
|  | CREATE TRIGGER notes_fts_protect  | ||||||
|  | AFTER UPDATE ON notes | ||||||
|  | WHEN OLD.isProtected = 0 AND NEW.isProtected = 1 | ||||||
|  | BEGIN | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for notes becoming unprotected | ||||||
|  | -- Add to FTS when a note becomes unprotected (if eligible) | ||||||
|  | CREATE TRIGGER notes_fts_unprotect  | ||||||
|  | AFTER UPDATE ON notes | ||||||
|  | WHEN OLD.isProtected = 1 AND NEW.isProtected = 0 | ||||||
|  |     AND NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |     AND NEW.isDeleted = 0 | ||||||
|  | BEGIN | ||||||
|  |     DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |      | ||||||
|  |     INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |     SELECT  | ||||||
|  |         NEW.noteId, | ||||||
|  |         NEW.title, | ||||||
|  |         COALESCE(b.content, '') | ||||||
|  |     FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |     LEFT JOIN blobs b ON b.blobId = NEW.blobId; | ||||||
|  | END; | ||||||
|  |  | ||||||
|  | -- Trigger for INSERT operations on blobs | ||||||
|  | -- Handles: INSERT, INSERT OR REPLACE, and the INSERT part of upsert | ||||||
|  | -- Updates all notes that reference this blob (common during import and deduplication) | ||||||
|  | CREATE TRIGGER notes_fts_blob_insert  | ||||||
|  | AFTER INSERT ON blobs | ||||||
|  | BEGIN | ||||||
|  |     -- Use INSERT OR REPLACE to handle both new and existing FTS entries | ||||||
|  |     -- This is crucial for blob deduplication where multiple notes may already | ||||||
|  |     -- exist that reference this blob before the blob itself is created | ||||||
|  |     INSERT OR REPLACE INTO notes_fts (noteId, title, content) | ||||||
|  |     SELECT  | ||||||
|  |         n.noteId, | ||||||
|  |         n.title, | ||||||
|  |         NEW.content | ||||||
|  |     FROM notes n | ||||||
|  |     WHERE n.blobId = NEW.blobId | ||||||
|  |         AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |         AND n.isDeleted = 0 | ||||||
|  |         AND n.isProtected = 0; | ||||||
|  | END; | ||||||
|   | |||||||
							
								
								
									
										553
									
								
								apps/server/src/migrations/0234__add_fts5_search.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										553
									
								
								apps/server/src/migrations/0234__add_fts5_search.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,553 @@ | |||||||
|  | /** | ||||||
|  |  * Migration to add FTS5 full-text search support and strategic performance indexes | ||||||
|  |  *  | ||||||
|  |  * This migration: | ||||||
|  |  * 1. Creates an FTS5 virtual table for full-text searching | ||||||
|  |  * 2. Populates it with existing note content | ||||||
|  |  * 3. Creates triggers to keep the FTS table synchronized with note changes | ||||||
|  |  * 4. Adds strategic composite and covering indexes for improved query performance | ||||||
|  |  * 5. Optimizes common query patterns identified through performance analysis | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import sql from "../services/sql.js"; | ||||||
|  | import log from "../services/log.js"; | ||||||
|  |  | ||||||
|  | export default function addFTS5SearchAndPerformanceIndexes() { | ||||||
|  |     log.info("Starting FTS5 and performance optimization migration..."); | ||||||
|  |  | ||||||
|  |     // Verify SQLite version supports trigram tokenizer (requires 3.34.0+) | ||||||
|  |     const sqliteVersion = sql.getValue<string>(`SELECT sqlite_version()`); | ||||||
|  |     const [major, minor, patch] = sqliteVersion.split('.').map(Number); | ||||||
|  |     const versionNumber = major * 10000 + minor * 100 + (patch || 0); | ||||||
|  |     const requiredVersion = 3 * 10000 + 34 * 100 + 0; // 3.34.0 | ||||||
|  |  | ||||||
|  |     if (versionNumber < requiredVersion) { | ||||||
|  |         log.error(`SQLite version ${sqliteVersion} does not support trigram tokenizer (requires 3.34.0+)`); | ||||||
|  |         log.info("Skipping FTS5 trigram migration - will use fallback search implementation"); | ||||||
|  |         return; // Skip FTS5 setup, rely on fallback search | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     log.info(`SQLite version ${sqliteVersion} confirmed - trigram tokenizer available`); | ||||||
|  |  | ||||||
|  |     // Part 1: FTS5 Setup | ||||||
|  |     log.info("Creating FTS5 virtual table for full-text search..."); | ||||||
|  |  | ||||||
|  |     // Create FTS5 virtual table | ||||||
|  |     // We store noteId, title, and content for searching | ||||||
|  |     sql.executeScript(` | ||||||
|  |         -- Drop existing FTS table if it exists (for re-running migration in dev) | ||||||
|  |         DROP TABLE IF EXISTS notes_fts; | ||||||
|  |          | ||||||
|  |         -- Create FTS5 virtual table with trigram tokenizer | ||||||
|  |         -- Trigram tokenizer provides language-agnostic substring matching: | ||||||
|  |         -- 1. Fast substring matching (50-100x speedup for LIKE queries without wildcards) | ||||||
|  |         -- 2. Case-insensitive search without custom collation | ||||||
|  |         -- 3. No language-specific stemming assumptions (works for all languages) | ||||||
|  |         -- 4. Boolean operators (AND, OR, NOT) and phrase matching with quotes | ||||||
|  |         -- | ||||||
|  |         -- IMPORTANT: Trigram requires minimum 3-character tokens for matching | ||||||
|  |         -- detail='none' reduces index size by ~50% while maintaining MATCH/rank performance | ||||||
|  |         -- (loses position info for highlight() function, but snippet() still works) | ||||||
|  |         CREATE VIRTUAL TABLE IF NOT EXISTS notes_fts USING fts5( | ||||||
|  |             noteId UNINDEXED, | ||||||
|  |             title, | ||||||
|  |             content, | ||||||
|  |             tokenize = 'trigram', | ||||||
|  |             detail = 'none' | ||||||
|  |         ); | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     log.info("Populating FTS5 table with existing note content..."); | ||||||
|  |  | ||||||
|  |     // Populate the FTS table with existing notes | ||||||
|  |     // We only index text-based note types that contain searchable content | ||||||
|  |     const batchSize = 100; | ||||||
|  |     let processedCount = 0; | ||||||
|  |     let hasError = false; | ||||||
|  |  | ||||||
|  |     // Wrap entire population process in a transaction for consistency | ||||||
|  |     // If any error occurs, the entire population will be rolled back | ||||||
|  |     try { | ||||||
|  |         sql.transactional(() => { | ||||||
|  |             let offset = 0; | ||||||
|  |              | ||||||
|  |             while (true) { | ||||||
|  |                 const notes = sql.getRows<{ | ||||||
|  |                     noteId: string; | ||||||
|  |                     title: string; | ||||||
|  |                     content: string | null; | ||||||
|  |                 }>(` | ||||||
|  |                     SELECT  | ||||||
|  |                         n.noteId, | ||||||
|  |                         n.title, | ||||||
|  |                         b.content | ||||||
|  |                     FROM notes n | ||||||
|  |                     LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                     WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                         AND n.isDeleted = 0 | ||||||
|  |                         AND n.isProtected = 0  -- Skip protected notes - they require special handling | ||||||
|  |                     ORDER BY n.noteId | ||||||
|  |                     LIMIT ? OFFSET ? | ||||||
|  |                 `, [batchSize, offset]); | ||||||
|  |  | ||||||
|  |                 if (notes.length === 0) { | ||||||
|  |                     break; | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 for (const note of notes) { | ||||||
|  |                     if (note.content) { | ||||||
|  |                         // Process content based on type (simplified for migration) | ||||||
|  |                         let processedContent = note.content; | ||||||
|  |                          | ||||||
|  |                         // For HTML content, we'll strip tags in the search service | ||||||
|  |                         // For now, just insert the raw content | ||||||
|  |                         sql.execute(` | ||||||
|  |                             INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |                             VALUES (?, ?, ?) | ||||||
|  |                         `, [note.noteId, note.title, processedContent]); | ||||||
|  |                         processedCount++; | ||||||
|  |                     } | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 offset += batchSize; | ||||||
|  |                  | ||||||
|  |                 if (processedCount % 1000 === 0) { | ||||||
|  |                     log.info(`Processed ${processedCount} notes for FTS indexing...`); | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |         }); | ||||||
|  |     } catch (error) { | ||||||
|  |         hasError = true; | ||||||
|  |         log.error(`Failed to populate FTS index. Rolling back... ${error}`); | ||||||
|  |         // Clean up partial data if transaction failed | ||||||
|  |         try { | ||||||
|  |             sql.execute("DELETE FROM notes_fts"); | ||||||
|  |         } catch (cleanupError) { | ||||||
|  |             log.error(`Failed to clean up FTS table after error: ${cleanupError}`); | ||||||
|  |         } | ||||||
|  |         throw new Error(`FTS5 migration failed during population: ${error}`); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     log.info(`Completed FTS indexing of ${processedCount} notes`); | ||||||
|  |  | ||||||
|  |     // Create triggers to keep FTS table synchronized | ||||||
|  |     log.info("Creating FTS synchronization triggers..."); | ||||||
|  |  | ||||||
|  |     // Drop all existing triggers first to ensure clean state | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_insert`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_update`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_delete`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_soft_delete`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_blob_insert`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_blob_update`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_protect`); | ||||||
|  |     sql.execute(`DROP TRIGGER IF EXISTS notes_fts_unprotect`); | ||||||
|  |  | ||||||
|  |     // Create improved triggers that handle all SQL operations properly | ||||||
|  |     // including INSERT OR REPLACE and INSERT ... ON CONFLICT ... DO UPDATE (upsert) | ||||||
|  |      | ||||||
|  |     // Trigger for INSERT operations on notes | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_insert  | ||||||
|  |         AFTER INSERT ON notes | ||||||
|  |         WHEN NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap')  | ||||||
|  |             AND NEW.isDeleted = 0 | ||||||
|  |             AND NEW.isProtected = 0 | ||||||
|  |         BEGIN | ||||||
|  |             -- First delete any existing FTS entry (in case of INSERT OR REPLACE) | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |              | ||||||
|  |             -- Then insert the new entry, using LEFT JOIN to handle missing blobs | ||||||
|  |             INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT  | ||||||
|  |                 NEW.noteId, | ||||||
|  |                 NEW.title, | ||||||
|  |                 COALESCE(b.content, '')  -- Use empty string if blob doesn't exist yet | ||||||
|  |             FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |             LEFT JOIN blobs b ON b.blobId = NEW.blobId; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for UPDATE operations on notes table | ||||||
|  |     // Fires for ANY update to searchable notes to ensure FTS stays in sync | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_update  | ||||||
|  |         AFTER UPDATE ON notes | ||||||
|  |         WHEN NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |             -- Fire on any change, not just specific columns, to handle all upsert scenarios | ||||||
|  |         BEGIN | ||||||
|  |             -- Always delete the old entry | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |              | ||||||
|  |             -- Insert new entry if note is not deleted and not protected | ||||||
|  |             INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT  | ||||||
|  |                 NEW.noteId, | ||||||
|  |                 NEW.title, | ||||||
|  |                 COALESCE(b.content, '')  -- Use empty string if blob doesn't exist yet | ||||||
|  |             FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |             LEFT JOIN blobs b ON b.blobId = NEW.blobId | ||||||
|  |             WHERE NEW.isDeleted = 0 | ||||||
|  |                 AND NEW.isProtected = 0; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for DELETE operations on notes | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_delete  | ||||||
|  |         AFTER DELETE ON notes | ||||||
|  |         BEGIN | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = OLD.noteId; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for soft delete (isDeleted = 1) | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_soft_delete  | ||||||
|  |         AFTER UPDATE ON notes | ||||||
|  |         WHEN OLD.isDeleted = 0 AND NEW.isDeleted = 1 | ||||||
|  |         BEGIN | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for notes becoming protected | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_protect  | ||||||
|  |         AFTER UPDATE ON notes | ||||||
|  |         WHEN OLD.isProtected = 0 AND NEW.isProtected = 1 | ||||||
|  |         BEGIN | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for notes becoming unprotected | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_unprotect  | ||||||
|  |         AFTER UPDATE ON notes | ||||||
|  |         WHEN OLD.isProtected = 1 AND NEW.isProtected = 0 | ||||||
|  |             AND NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |             AND NEW.isDeleted = 0 | ||||||
|  |         BEGIN | ||||||
|  |             DELETE FROM notes_fts WHERE noteId = NEW.noteId; | ||||||
|  |              | ||||||
|  |             INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT  | ||||||
|  |                 NEW.noteId, | ||||||
|  |                 NEW.title, | ||||||
|  |                 COALESCE(b.content, '') | ||||||
|  |             FROM (SELECT NEW.noteId) AS note_select | ||||||
|  |             LEFT JOIN blobs b ON b.blobId = NEW.blobId; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for INSERT operations on blobs | ||||||
|  |     // Uses INSERT OR REPLACE for efficiency with deduplicated blobs | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_blob_insert  | ||||||
|  |         AFTER INSERT ON blobs | ||||||
|  |         BEGIN | ||||||
|  |             -- Use INSERT OR REPLACE for atomic update | ||||||
|  |             -- This handles the case where FTS entries may already exist | ||||||
|  |             INSERT OR REPLACE INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT  | ||||||
|  |                 n.noteId, | ||||||
|  |                 n.title, | ||||||
|  |                 NEW.content | ||||||
|  |             FROM notes n | ||||||
|  |             WHERE n.blobId = NEW.blobId | ||||||
|  |                 AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                 AND n.isDeleted = 0 | ||||||
|  |                 AND n.isProtected = 0; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     // Trigger for UPDATE operations on blobs | ||||||
|  |     // Uses INSERT OR REPLACE for efficiency | ||||||
|  |     sql.execute(` | ||||||
|  |         CREATE TRIGGER notes_fts_blob_update  | ||||||
|  |         AFTER UPDATE ON blobs | ||||||
|  |         BEGIN | ||||||
|  |             -- Use INSERT OR REPLACE for atomic update | ||||||
|  |             INSERT OR REPLACE INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT  | ||||||
|  |                 n.noteId, | ||||||
|  |                 n.title, | ||||||
|  |                 NEW.content | ||||||
|  |             FROM notes n | ||||||
|  |             WHERE n.blobId = NEW.blobId | ||||||
|  |                 AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                 AND n.isDeleted = 0 | ||||||
|  |                 AND n.isProtected = 0; | ||||||
|  |         END | ||||||
|  |     `); | ||||||
|  |  | ||||||
|  |     log.info("FTS5 setup completed successfully"); | ||||||
|  |      | ||||||
|  |     // Final cleanup: ensure all eligible notes are indexed | ||||||
|  |     // This catches any edge cases where notes might have been missed | ||||||
|  |     log.info("Running final FTS index cleanup..."); | ||||||
|  |      | ||||||
|  |     // First check for missing notes | ||||||
|  |     const missingCount = sql.getValue<number>(` | ||||||
|  |         SELECT COUNT(*) FROM notes n | ||||||
|  |         LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |         WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |             AND n.isDeleted = 0 | ||||||
|  |             AND n.isProtected = 0 | ||||||
|  |             AND b.content IS NOT NULL | ||||||
|  |             AND NOT EXISTS (SELECT 1 FROM notes_fts WHERE noteId = n.noteId) | ||||||
|  |     `) || 0; | ||||||
|  |      | ||||||
|  |     if (missingCount > 0) { | ||||||
|  |         // Insert missing notes | ||||||
|  |         sql.execute(` | ||||||
|  |             WITH missing_notes AS ( | ||||||
|  |                 SELECT n.noteId, n.title, b.content | ||||||
|  |                 FROM notes n | ||||||
|  |                 LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                 WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                     AND n.isDeleted = 0 | ||||||
|  |                     AND n.isProtected = 0 | ||||||
|  |                     AND b.content IS NOT NULL | ||||||
|  |                     AND NOT EXISTS (SELECT 1 FROM notes_fts WHERE noteId = n.noteId) | ||||||
|  |             ) | ||||||
|  |             INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |             SELECT noteId, title, content FROM missing_notes | ||||||
|  |         `); | ||||||
|  |     } | ||||||
|  |      | ||||||
|  |     const cleanupCount = missingCount; | ||||||
|  |      | ||||||
|  |     if (cleanupCount && cleanupCount > 0) { | ||||||
|  |         log.info(`Indexed ${cleanupCount} additional notes during cleanup`); | ||||||
|  |     } | ||||||
|  |      | ||||||
|  |     // ======================================== | ||||||
|  |     // Part 2: Strategic Performance Indexes | ||||||
|  |     // ======================================== | ||||||
|  |      | ||||||
|  |     log.info("Adding strategic performance indexes..."); | ||||||
|  |     const startTime = Date.now(); | ||||||
|  |     const indexesCreated: string[] = []; | ||||||
|  |  | ||||||
|  |     try { | ||||||
|  |         // ======================================== | ||||||
|  |         // NOTES TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for common search filters | ||||||
|  |         log.info("Creating composite index on notes table for search filters..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_notes_search_composite; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_notes_search_composite  | ||||||
|  |             ON notes (isDeleted, type, mime, dateModified DESC); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_notes_search_composite"); | ||||||
|  |  | ||||||
|  |         // Covering index for note metadata queries | ||||||
|  |         log.info("Creating covering index for note metadata..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_notes_metadata_covering; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_notes_metadata_covering  | ||||||
|  |             ON notes (noteId, isDeleted, type, mime, title, dateModified, isProtected); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_notes_metadata_covering"); | ||||||
|  |  | ||||||
|  |         // Index for protected notes filtering | ||||||
|  |         log.info("Creating index for protected notes..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_notes_protected_deleted; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_notes_protected_deleted  | ||||||
|  |             ON notes (isProtected, isDeleted)  | ||||||
|  |             WHERE isProtected = 1; | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_notes_protected_deleted"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // BRANCHES TABLE INDEXES   | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for tree traversal | ||||||
|  |         log.info("Creating composite index on branches for tree traversal..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_branches_tree_traversal; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_branches_tree_traversal  | ||||||
|  |             ON branches (parentNoteId, isDeleted, notePosition); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_branches_tree_traversal"); | ||||||
|  |  | ||||||
|  |         // Covering index for branch queries | ||||||
|  |         log.info("Creating covering index for branch queries..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_branches_covering; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_branches_covering  | ||||||
|  |             ON branches (noteId, parentNoteId, isDeleted, notePosition, prefix); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_branches_covering"); | ||||||
|  |  | ||||||
|  |         // Index for finding all parents of a note | ||||||
|  |         log.info("Creating index for reverse tree lookup..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_branches_note_parents; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_branches_note_parents  | ||||||
|  |             ON branches (noteId, isDeleted)  | ||||||
|  |             WHERE isDeleted = 0; | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_branches_note_parents"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // ATTRIBUTES TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for attribute searches | ||||||
|  |         log.info("Creating composite index on attributes for search..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attributes_search_composite; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attributes_search_composite  | ||||||
|  |             ON attributes (name, value, isDeleted); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attributes_search_composite"); | ||||||
|  |  | ||||||
|  |         // Covering index for attribute queries | ||||||
|  |         log.info("Creating covering index for attribute queries..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attributes_covering; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attributes_covering  | ||||||
|  |             ON attributes (noteId, name, value, type, isDeleted, position); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attributes_covering"); | ||||||
|  |  | ||||||
|  |         // Index for inherited attributes | ||||||
|  |         log.info("Creating index for inherited attributes..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attributes_inheritable; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attributes_inheritable  | ||||||
|  |             ON attributes (isInheritable, isDeleted)  | ||||||
|  |             WHERE isInheritable = 1 AND isDeleted = 0; | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attributes_inheritable"); | ||||||
|  |  | ||||||
|  |         // Index for specific attribute types | ||||||
|  |         log.info("Creating index for label attributes..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attributes_labels; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attributes_labels  | ||||||
|  |             ON attributes (type, name, value)  | ||||||
|  |             WHERE type = 'label' AND isDeleted = 0; | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attributes_labels"); | ||||||
|  |  | ||||||
|  |         log.info("Creating index for relation attributes..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attributes_relations; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attributes_relations  | ||||||
|  |             ON attributes (type, name, value)  | ||||||
|  |             WHERE type = 'relation' AND isDeleted = 0; | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attributes_relations"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // BLOBS TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Index for blob content size filtering | ||||||
|  |         log.info("Creating index for blob content size..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_blobs_content_size; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_blobs_content_size  | ||||||
|  |             ON blobs (blobId, LENGTH(content)); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_blobs_content_size"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // ATTACHMENTS TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for attachment queries | ||||||
|  |         log.info("Creating composite index for attachments..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_attachments_composite; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_attachments_composite  | ||||||
|  |             ON attachments (ownerId, role, isDeleted, position); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_attachments_composite"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // REVISIONS TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for revision queries | ||||||
|  |         log.info("Creating composite index for revisions..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_revisions_note_date; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_revisions_note_date  | ||||||
|  |             ON revisions (noteId, utcDateCreated DESC); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_revisions_note_date"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // ENTITY_CHANGES TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Composite index for sync operations | ||||||
|  |         log.info("Creating composite index for entity changes sync..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_entity_changes_sync; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_entity_changes_sync  | ||||||
|  |             ON entity_changes (isSynced, utcDateChanged); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_entity_changes_sync"); | ||||||
|  |  | ||||||
|  |         // Index for component-based queries | ||||||
|  |         log.info("Creating index for component-based entity change queries..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_entity_changes_component; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_entity_changes_component  | ||||||
|  |             ON entity_changes (componentId, utcDateChanged DESC); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_entity_changes_component"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // RECENT_NOTES TABLE INDEXES | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         // Index for recent notes ordering | ||||||
|  |         log.info("Creating index for recent notes..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             DROP INDEX IF EXISTS IDX_recent_notes_date; | ||||||
|  |             CREATE INDEX IF NOT EXISTS IDX_recent_notes_date  | ||||||
|  |             ON recent_notes (utcDateCreated DESC); | ||||||
|  |         `); | ||||||
|  |         indexesCreated.push("IDX_recent_notes_date"); | ||||||
|  |  | ||||||
|  |         // ======================================== | ||||||
|  |         // ANALYZE TABLES FOR QUERY PLANNER | ||||||
|  |         // ======================================== | ||||||
|  |          | ||||||
|  |         log.info("Running ANALYZE to update SQLite query planner statistics..."); | ||||||
|  |         sql.executeScript(` | ||||||
|  |             ANALYZE notes; | ||||||
|  |             ANALYZE branches; | ||||||
|  |             ANALYZE attributes; | ||||||
|  |             ANALYZE blobs; | ||||||
|  |             ANALYZE attachments; | ||||||
|  |             ANALYZE revisions; | ||||||
|  |             ANALYZE entity_changes; | ||||||
|  |             ANALYZE recent_notes; | ||||||
|  |             ANALYZE notes_fts; | ||||||
|  |         `); | ||||||
|  |  | ||||||
|  |         const endTime = Date.now(); | ||||||
|  |         const duration = endTime - startTime; | ||||||
|  |          | ||||||
|  |         log.info(`Performance index creation completed in ${duration}ms`); | ||||||
|  |         log.info(`Created ${indexesCreated.length} indexes: ${indexesCreated.join(", ")}`); | ||||||
|  |  | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`Error creating performance indexes: ${error}`); | ||||||
|  |         throw error; | ||||||
|  |     } | ||||||
|  |      | ||||||
|  |     log.info("FTS5 and performance optimization migration completed successfully"); | ||||||
|  | } | ||||||
							
								
								
									
										47
									
								
								apps/server/src/migrations/0236__cleanup_sqlite_search.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										47
									
								
								apps/server/src/migrations/0236__cleanup_sqlite_search.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,47 @@ | |||||||
|  | /** | ||||||
|  |  * Migration to clean up custom SQLite search implementation | ||||||
|  |  * | ||||||
|  |  * This migration removes tables and triggers created by migration 0235 | ||||||
|  |  * which implemented a custom SQLite-based search system. That system | ||||||
|  |  * has been replaced by FTS5 with trigram tokenizer (migration 0234), | ||||||
|  |  * making these custom tables redundant. | ||||||
|  |  * | ||||||
|  |  * Tables removed: | ||||||
|  |  * - note_search_content: Stored normalized note content for custom search | ||||||
|  |  * - note_tokens: Stored tokenized words for custom token-based search | ||||||
|  |  * | ||||||
|  |  * This migration is safe to run on databases that: | ||||||
|  |  * 1. Never ran migration 0235 (tables don't exist) | ||||||
|  |  * 2. Already ran migration 0235 (tables will be dropped) | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import sql from "../services/sql.js"; | ||||||
|  | import log from "../services/log.js"; | ||||||
|  |  | ||||||
|  | export default function cleanupSqliteSearch() { | ||||||
|  |     log.info("Starting SQLite custom search cleanup migration..."); | ||||||
|  |  | ||||||
|  |     try { | ||||||
|  |         sql.transactional(() => { | ||||||
|  |             // Drop custom search tables if they exist | ||||||
|  |             log.info("Dropping note_search_content table..."); | ||||||
|  |             sql.executeScript(`DROP TABLE IF EXISTS note_search_content`); | ||||||
|  |  | ||||||
|  |             log.info("Dropping note_tokens table..."); | ||||||
|  |             sql.executeScript(`DROP TABLE IF EXISTS note_tokens`); | ||||||
|  |  | ||||||
|  |             // Clean up any entity changes for these tables | ||||||
|  |             // This prevents sync issues and cleans up change tracking | ||||||
|  |             log.info("Cleaning up entity changes for removed tables..."); | ||||||
|  |             sql.execute(` | ||||||
|  |                 DELETE FROM entity_changes | ||||||
|  |                 WHERE entityName IN ('note_search_content', 'note_tokens') | ||||||
|  |             `); | ||||||
|  |  | ||||||
|  |             log.info("SQLite custom search cleanup completed successfully"); | ||||||
|  |         }); | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`Error during SQLite search cleanup: ${error}`); | ||||||
|  |         throw new Error(`Failed to clean up SQLite search tables: ${error}`); | ||||||
|  |     } | ||||||
|  | } | ||||||
| @@ -6,6 +6,16 @@ | |||||||
|  |  | ||||||
| // Migrations should be kept in descending order, so the latest migration is first. | // Migrations should be kept in descending order, so the latest migration is first. | ||||||
| const MIGRATIONS: (SqlMigration | JsMigration)[] = [ | const MIGRATIONS: (SqlMigration | JsMigration)[] = [ | ||||||
|  |     // Clean up custom SQLite search tables (replaced by FTS5 trigram) | ||||||
|  |     { | ||||||
|  |         version: 236, | ||||||
|  |         module: async () => import("./0236__cleanup_sqlite_search.js") | ||||||
|  |     }, | ||||||
|  |     // Add FTS5 full-text search support and strategic performance indexes | ||||||
|  |     { | ||||||
|  |         version: 234, | ||||||
|  |         module: async () => import("./0234__add_fts5_search.js") | ||||||
|  |     }, | ||||||
|     // Migrate geo map to collection |     // Migrate geo map to collection | ||||||
|     { |     { | ||||||
|         version: 233, |         version: 233, | ||||||
|   | |||||||
| @@ -98,6 +98,9 @@ async function importNotesToBranch(req: Request) { | |||||||
|     // import has deactivated note events so becca is not updated, instead we force it to reload |     // import has deactivated note events so becca is not updated, instead we force it to reload | ||||||
|     beccaLoader.load(); |     beccaLoader.load(); | ||||||
|  |  | ||||||
|  |     // FTS indexing is now handled directly during note creation when entity events are disabled | ||||||
|  |     // This ensures all imported notes are immediately searchable without needing a separate sync step | ||||||
|  |  | ||||||
|     return note.getPojo(); |     return note.getPojo(); | ||||||
| } | } | ||||||
|  |  | ||||||
|   | |||||||
| @@ -10,6 +10,8 @@ import cls from "../../services/cls.js"; | |||||||
| import attributeFormatter from "../../services/attribute_formatter.js"; | import attributeFormatter from "../../services/attribute_formatter.js"; | ||||||
| import ValidationError from "../../errors/validation_error.js"; | import ValidationError from "../../errors/validation_error.js"; | ||||||
| import type SearchResult from "../../services/search/search_result.js"; | import type SearchResult from "../../services/search/search_result.js"; | ||||||
|  | import ftsSearchService from "../../services/search/fts_search.js"; | ||||||
|  | import log from "../../services/log.js"; | ||||||
|  |  | ||||||
| function searchFromNote(req: Request): SearchNoteResult { | function searchFromNote(req: Request): SearchNoteResult { | ||||||
|     const note = becca.getNoteOrThrow(req.params.noteId); |     const note = becca.getNoteOrThrow(req.params.noteId); | ||||||
| @@ -129,11 +131,86 @@ function searchTemplates() { | |||||||
|         .map((note) => note.noteId); |         .map((note) => note.noteId); | ||||||
| } | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Syncs missing notes to the FTS index | ||||||
|  |  * This endpoint is useful for maintenance or after imports where FTS triggers might not have fired | ||||||
|  |  */ | ||||||
|  | function syncFtsIndex(req: Request) { | ||||||
|  |     try { | ||||||
|  |         const noteIds = req.body?.noteIds; | ||||||
|  |          | ||||||
|  |         log.info(`FTS sync requested for ${noteIds?.length || 'all'} notes`); | ||||||
|  |          | ||||||
|  |         const syncedCount = ftsSearchService.syncMissingNotes(noteIds); | ||||||
|  |          | ||||||
|  |         return { | ||||||
|  |             success: true, | ||||||
|  |             syncedCount, | ||||||
|  |             message: syncedCount > 0  | ||||||
|  |                 ? `Successfully synced ${syncedCount} notes to FTS index`  | ||||||
|  |                 : 'FTS index is already up to date' | ||||||
|  |         }; | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`FTS sync failed: ${error}`); | ||||||
|  |         throw new ValidationError(`Failed to sync FTS index: ${error}`); | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Rebuilds the entire FTS index from scratch | ||||||
|  |  * This is a more intensive operation that should be used sparingly | ||||||
|  |  */ | ||||||
|  | function rebuildFtsIndex() { | ||||||
|  |     try { | ||||||
|  |         log.info('FTS index rebuild requested'); | ||||||
|  |          | ||||||
|  |         ftsSearchService.rebuildIndex(); | ||||||
|  |          | ||||||
|  |         return { | ||||||
|  |             success: true, | ||||||
|  |             message: 'FTS index rebuild completed successfully' | ||||||
|  |         }; | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`FTS rebuild failed: ${error}`); | ||||||
|  |         throw new ValidationError(`Failed to rebuild FTS index: ${error}`); | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Gets statistics about the FTS index | ||||||
|  |  */ | ||||||
|  | function getFtsIndexStats() { | ||||||
|  |     try { | ||||||
|  |         const stats = ftsSearchService.getIndexStats(); | ||||||
|  |          | ||||||
|  |         // Get count of notes that should be indexed | ||||||
|  |         const eligibleNotesCount = searchService.searchNotes('', { | ||||||
|  |             includeArchivedNotes: false, | ||||||
|  |             ignoreHoistedNote: true | ||||||
|  |         }).filter(note =>  | ||||||
|  |             ['text', 'code', 'mermaid', 'canvas', 'mindMap'].includes(note.type) && | ||||||
|  |             !note.isProtected | ||||||
|  |         ).length; | ||||||
|  |          | ||||||
|  |         return { | ||||||
|  |             ...stats, | ||||||
|  |             eligibleNotesCount, | ||||||
|  |             missingFromIndex: Math.max(0, eligibleNotesCount - stats.totalDocuments) | ||||||
|  |         }; | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`Failed to get FTS stats: ${error}`); | ||||||
|  |         throw new ValidationError(`Failed to get FTS index statistics: ${error}`); | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
| export default { | export default { | ||||||
|     searchFromNote, |     searchFromNote, | ||||||
|     searchAndExecute, |     searchAndExecute, | ||||||
|     getRelatedNotes, |     getRelatedNotes, | ||||||
|     quickSearch, |     quickSearch, | ||||||
|     search, |     search, | ||||||
|     searchTemplates |     searchTemplates, | ||||||
|  |     syncFtsIndex, | ||||||
|  |     rebuildFtsIndex, | ||||||
|  |     getFtsIndexStats | ||||||
| }; | }; | ||||||
|   | |||||||
| @@ -11,7 +11,7 @@ import auth from "../services/auth.js"; | |||||||
| import { doubleCsrfProtection as csrfMiddleware } from "./csrf_protection.js"; | import { doubleCsrfProtection as csrfMiddleware } from "./csrf_protection.js"; | ||||||
| import { safeExtractMessageAndStackFromError } from "../services/utils.js"; | import { safeExtractMessageAndStackFromError } from "../services/utils.js"; | ||||||
|  |  | ||||||
| const MAX_ALLOWED_FILE_SIZE_MB = 250; | const MAX_ALLOWED_FILE_SIZE_MB = 2500; | ||||||
| export const router = express.Router(); | export const router = express.Router(); | ||||||
|  |  | ||||||
| // TODO: Deduplicate with etapi_utils.ts afterwards. | // TODO: Deduplicate with etapi_utils.ts afterwards. | ||||||
| @@ -183,7 +183,7 @@ export function createUploadMiddleware(): RequestHandler { | |||||||
|  |  | ||||||
|     if (!process.env.TRILIUM_NO_UPLOAD_LIMIT) { |     if (!process.env.TRILIUM_NO_UPLOAD_LIMIT) { | ||||||
|         multerOptions.limits = { |         multerOptions.limits = { | ||||||
|             fileSize: MAX_ALLOWED_FILE_SIZE_MB * 1024 * 1024 |             fileSize: MAX_ALLOWED_FILE_SIZE_MB * 1024 * 1024 * 1024 | ||||||
|         }; |         }; | ||||||
|     } |     } | ||||||
|  |  | ||||||
|   | |||||||
| @@ -4,7 +4,7 @@ import packageJson from "../../package.json" with { type: "json" }; | |||||||
| import dataDir from "./data_dir.js"; | import dataDir from "./data_dir.js"; | ||||||
| import { AppInfo } from "@triliumnext/commons"; | import { AppInfo } from "@triliumnext/commons"; | ||||||
|  |  | ||||||
| const APP_DB_VERSION = 233; | const APP_DB_VERSION = 236; | ||||||
| const SYNC_VERSION = 36; | const SYNC_VERSION = 36; | ||||||
| const CLIPPER_PROTOCOL_VERSION = "1.0"; | const CLIPPER_PROTOCOL_VERSION = "1.0"; | ||||||
|  |  | ||||||
|   | |||||||
| @@ -214,6 +214,14 @@ function createNewNote(params: NoteParams): { | |||||||
|                 prefix: params.prefix || "", |                 prefix: params.prefix || "", | ||||||
|                 isExpanded: !!params.isExpanded |                 isExpanded: !!params.isExpanded | ||||||
|             }).save(); |             }).save(); | ||||||
|  |              | ||||||
|  |             // FTS indexing is now handled entirely by database triggers | ||||||
|  |             // The improved triggers in schema.sql handle all scenarios including: | ||||||
|  |             // - INSERT OR REPLACE operations | ||||||
|  |             // - INSERT ... ON CONFLICT ... DO UPDATE (upsert)  | ||||||
|  |             // - Cases where notes are created before blobs (common during import) | ||||||
|  |             // - All UPDATE scenarios, not just specific column changes | ||||||
|  |             // This ensures FTS stays in sync even when entity events are disabled | ||||||
|         } finally { |         } finally { | ||||||
|             if (!isEntityEventsDisabled) { |             if (!isEntityEventsDisabled) { | ||||||
|                 // re-enable entity events only if they were previously enabled |                 // re-enable entity events only if they were previously enabled | ||||||
|   | |||||||
| @@ -19,6 +19,7 @@ import { | |||||||
|     fuzzyMatchWord, |     fuzzyMatchWord, | ||||||
|     FUZZY_SEARCH_CONFIG  |     FUZZY_SEARCH_CONFIG  | ||||||
| } from "../utils/text_utils.js"; | } from "../utils/text_utils.js"; | ||||||
|  | import ftsSearchService, { FTSError, FTSNotAvailableError, FTSQueryError } from "../fts_search.js"; | ||||||
|  |  | ||||||
| const ALLOWED_OPERATORS = new Set(["=", "!=", "*=*", "*=", "=*", "%=", "~=", "~*"]); | const ALLOWED_OPERATORS = new Set(["=", "!=", "*=*", "*=", "=*", "%=", "~=", "~*"]); | ||||||
|  |  | ||||||
| @@ -77,6 +78,105 @@ class NoteContentFulltextExp extends Expression { | |||||||
|  |  | ||||||
|         const resultNoteSet = new NoteSet(); |         const resultNoteSet = new NoteSet(); | ||||||
|  |  | ||||||
|  |         // Try to use FTS5 if available for better performance | ||||||
|  |         if (ftsSearchService.checkFTS5Availability() && this.canUseFTS5()) { | ||||||
|  |             try { | ||||||
|  |                 // Check if we need to search protected notes | ||||||
|  |                 const searchProtected = protectedSessionService.isProtectedSessionAvailable(); | ||||||
|  |  | ||||||
|  |                 const noteIdSet = inputNoteSet.getNoteIds(); | ||||||
|  |  | ||||||
|  |                 // Determine which FTS5 method to use based on operator | ||||||
|  |                 let ftsResults; | ||||||
|  |                 if (this.operator === "*=*" || this.operator === "*=" || this.operator === "=*") { | ||||||
|  |                     // Substring operators use LIKE queries (optimized by trigram index) | ||||||
|  |                     // Do NOT pass a limit - we want all results to match traditional search behavior | ||||||
|  |                     ftsResults = ftsSearchService.searchWithLike( | ||||||
|  |                         this.tokens, | ||||||
|  |                         this.operator, | ||||||
|  |                         noteIdSet.size > 0 ? noteIdSet : undefined, | ||||||
|  |                         { | ||||||
|  |                             includeSnippets: false, | ||||||
|  |                             searchProtected: false | ||||||
|  |                             // No limit specified - return all results | ||||||
|  |                         }, | ||||||
|  |                         searchContext // Pass context to track internal timing | ||||||
|  |                     ); | ||||||
|  |                 } else { | ||||||
|  |                     // Other operators use MATCH syntax | ||||||
|  |                     ftsResults = ftsSearchService.searchSync( | ||||||
|  |                         this.tokens, | ||||||
|  |                         this.operator, | ||||||
|  |                         noteIdSet.size > 0 ? noteIdSet : undefined, | ||||||
|  |                         { | ||||||
|  |                             includeSnippets: false, | ||||||
|  |                             searchProtected: false // FTS5 doesn't index protected notes | ||||||
|  |                         }, | ||||||
|  |                         searchContext // Pass context to track internal timing | ||||||
|  |                     ); | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 // Add FTS results to note set | ||||||
|  |                 for (const result of ftsResults) { | ||||||
|  |                     if (becca.notes[result.noteId]) { | ||||||
|  |                         resultNoteSet.add(becca.notes[result.noteId]); | ||||||
|  |                     } | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 // If we need to search protected notes, use the separate method | ||||||
|  |                 if (searchProtected) { | ||||||
|  |                     const protectedResults = ftsSearchService.searchProtectedNotesSync( | ||||||
|  |                         this.tokens, | ||||||
|  |                         this.operator, | ||||||
|  |                         noteIdSet.size > 0 ? noteIdSet : undefined, | ||||||
|  |                         { | ||||||
|  |                             includeSnippets: false | ||||||
|  |                         } | ||||||
|  |                     ); | ||||||
|  |  | ||||||
|  |                     // Add protected note results | ||||||
|  |                     for (const result of protectedResults) { | ||||||
|  |                         if (becca.notes[result.noteId]) { | ||||||
|  |                             resultNoteSet.add(becca.notes[result.noteId]); | ||||||
|  |                         } | ||||||
|  |                     } | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 // Handle special cases that FTS5 doesn't support well | ||||||
|  |                 if (this.operator === "%=" || this.flatText) { | ||||||
|  |                     // Fall back to original implementation for regex and flat text searches | ||||||
|  |                     return this.executeWithFallback(inputNoteSet, resultNoteSet, searchContext); | ||||||
|  |                 } | ||||||
|  |  | ||||||
|  |                 return resultNoteSet; | ||||||
|  |             } catch (error) { | ||||||
|  |                 // Handle structured errors from FTS service | ||||||
|  |                 if (error instanceof FTSError) { | ||||||
|  |                     if (error instanceof FTSNotAvailableError) { | ||||||
|  |                         log.info("FTS5 not available, using standard search"); | ||||||
|  |                     } else if (error instanceof FTSQueryError) { | ||||||
|  |                         log.error(`FTS5 query error: ${error.message}`); | ||||||
|  |                         searchContext.addError(`Search optimization failed: ${error.message}`); | ||||||
|  |                     } else { | ||||||
|  |                         log.error(`FTS5 error: ${error}`); | ||||||
|  |                     } | ||||||
|  |  | ||||||
|  |                     // Use fallback for recoverable errors | ||||||
|  |                     if (error.recoverable) { | ||||||
|  |                         log.info("Using fallback search implementation"); | ||||||
|  |                     } else { | ||||||
|  |                         // For non-recoverable errors, return empty result | ||||||
|  |                         searchContext.addError(`Search failed: ${error.message}`); | ||||||
|  |                         return resultNoteSet; | ||||||
|  |                     } | ||||||
|  |                 } else { | ||||||
|  |                     log.error(`Unexpected error in FTS5 search: ${error}`); | ||||||
|  |                 } | ||||||
|  |                 // Fall back to original implementation | ||||||
|  |             } | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Original implementation for fallback or when FTS5 is not available | ||||||
|         for (const row of sql.iterateRows<SearchRow>(` |         for (const row of sql.iterateRows<SearchRow>(` | ||||||
|                 SELECT noteId, type, mime, content, isProtected |                 SELECT noteId, type, mime, content, isProtected | ||||||
|                 FROM notes JOIN blobs USING (blobId) |                 FROM notes JOIN blobs USING (blobId) | ||||||
| @@ -89,6 +189,39 @@ class NoteContentFulltextExp extends Expression { | |||||||
|         return resultNoteSet; |         return resultNoteSet; | ||||||
|     } |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Determines if the current search can use FTS5 | ||||||
|  |      */ | ||||||
|  |     private canUseFTS5(): boolean { | ||||||
|  |         // FTS5 doesn't support regex searches well | ||||||
|  |         if (this.operator === "%=") { | ||||||
|  |             return false; | ||||||
|  |         } | ||||||
|  |          | ||||||
|  |         // For now, we'll use FTS5 for most text searches | ||||||
|  |         // but keep the original implementation for complex cases | ||||||
|  |         return true; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Executes search with fallback for special cases | ||||||
|  |      */ | ||||||
|  |     private executeWithFallback(inputNoteSet: NoteSet, resultNoteSet: NoteSet, searchContext: SearchContext): NoteSet { | ||||||
|  |         // Keep existing results from FTS5 and add additional results from fallback | ||||||
|  |         for (const row of sql.iterateRows<SearchRow>(` | ||||||
|  |                 SELECT noteId, type, mime, content, isProtected | ||||||
|  |                 FROM notes JOIN blobs USING (blobId) | ||||||
|  |                 WHERE type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap')  | ||||||
|  |                   AND isDeleted = 0  | ||||||
|  |                   AND LENGTH(content) < ${MAX_SEARCH_CONTENT_SIZE}`)) { | ||||||
|  |             if (this.operator === "%=" || this.flatText) { | ||||||
|  |                 // Only process for special cases | ||||||
|  |                 this.findInText(row, inputNoteSet, resultNoteSet); | ||||||
|  |             } | ||||||
|  |         } | ||||||
|  |         return resultNoteSet; | ||||||
|  |     } | ||||||
|  |  | ||||||
|     findInText({ noteId, isProtected, content, type, mime }: SearchRow, inputNoteSet: NoteSet, resultNoteSet: NoteSet) { |     findInText({ noteId, isProtected, content, type, mime }: SearchRow, inputNoteSet: NoteSet, resultNoteSet: NoteSet) { | ||||||
|         if (!inputNoteSet.hasNoteId(noteId) || !(noteId in becca.notes)) { |         if (!inputNoteSet.hasNoteId(noteId) || !(noteId in becca.notes)) { | ||||||
|             return; |             return; | ||||||
|   | |||||||
							
								
								
									
										1316
									
								
								apps/server/src/services/search/fts_search.test.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										1316
									
								
								apps/server/src/services/search/fts_search.test.ts
									
									
									
									
									
										Normal file
									
								
							
										
											
												File diff suppressed because it is too large
												Load Diff
											
										
									
								
							
							
								
								
									
										953
									
								
								apps/server/src/services/search/fts_search.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										953
									
								
								apps/server/src/services/search/fts_search.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,953 @@ | |||||||
|  | /** | ||||||
|  |  * FTS5 Search Service | ||||||
|  |  * | ||||||
|  |  * Encapsulates all FTS5-specific operations for full-text searching. | ||||||
|  |  * Provides efficient text search using SQLite's FTS5 extension with: | ||||||
|  |  * - Trigram tokenization for fast substring matching | ||||||
|  |  * - Snippet extraction for context | ||||||
|  |  * - Highlighting of matched terms | ||||||
|  |  * - Query syntax conversion from Trilium to FTS5 | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import sql from "../sql.js"; | ||||||
|  | import log from "../log.js"; | ||||||
|  | import protectedSessionService from "../protected_session.js"; | ||||||
|  | import striptags from "striptags"; | ||||||
|  | import { normalize } from "../utils.js"; | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Custom error classes for FTS operations | ||||||
|  |  */ | ||||||
|  | export class FTSError extends Error { | ||||||
|  |     constructor(message: string, public readonly code: string, public readonly recoverable: boolean = true) { | ||||||
|  |         super(message); | ||||||
|  |         this.name = 'FTSError'; | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export class FTSNotAvailableError extends FTSError { | ||||||
|  |     constructor(message: string = "FTS5 is not available") { | ||||||
|  |         super(message, 'FTS_NOT_AVAILABLE', true); | ||||||
|  |         this.name = 'FTSNotAvailableError'; | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export class FTSQueryError extends FTSError { | ||||||
|  |     constructor(message: string, public readonly query?: string) { | ||||||
|  |         super(message, 'FTS_QUERY_ERROR', true); | ||||||
|  |         this.name = 'FTSQueryError'; | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export interface FTSSearchResult { | ||||||
|  |     noteId: string; | ||||||
|  |     title: string; | ||||||
|  |     score: number; | ||||||
|  |     snippet?: string; | ||||||
|  |     highlights?: string[]; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export interface FTSSearchOptions { | ||||||
|  |     limit?: number; | ||||||
|  |     offset?: number; | ||||||
|  |     includeSnippets?: boolean; | ||||||
|  |     snippetLength?: number; | ||||||
|  |     highlightTag?: string; | ||||||
|  |     searchProtected?: boolean; | ||||||
|  |     skipDiagnostics?: boolean; // Skip diagnostic queries for performance measurements | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export interface FTSErrorInfo { | ||||||
|  |     error: FTSError; | ||||||
|  |     fallbackUsed: boolean; | ||||||
|  |     message: string; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Configuration for FTS5 search operations | ||||||
|  |  */ | ||||||
|  | const FTS_CONFIG = { | ||||||
|  |     /** Maximum number of results to return by default */ | ||||||
|  |     DEFAULT_LIMIT: 100, | ||||||
|  |     /** Default snippet length in tokens */ | ||||||
|  |     DEFAULT_SNIPPET_LENGTH: 30, | ||||||
|  |     /** Default highlight tags */ | ||||||
|  |     DEFAULT_HIGHLIGHT_START: '<mark>', | ||||||
|  |     DEFAULT_HIGHLIGHT_END: '</mark>', | ||||||
|  |     /** Maximum query length to prevent DoS */ | ||||||
|  |     MAX_QUERY_LENGTH: 1000, | ||||||
|  |     /** Snippet column indices */ | ||||||
|  |     SNIPPET_COLUMN_TITLE: 1, | ||||||
|  |     SNIPPET_COLUMN_CONTENT: 2, | ||||||
|  | }; | ||||||
|  |  | ||||||
|  | class FTSSearchService { | ||||||
|  |     private isFTS5Available: boolean | null = null; | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Checks if FTS5 is available in the current SQLite instance | ||||||
|  |      */ | ||||||
|  |     checkFTS5Availability(): boolean { | ||||||
|  |         if (this.isFTS5Available !== null) { | ||||||
|  |             return this.isFTS5Available; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Check if FTS5 module is available | ||||||
|  |             const result = sql.getValue<number>(` | ||||||
|  |                 SELECT COUNT(*)  | ||||||
|  |                 FROM sqlite_master  | ||||||
|  |                 WHERE type = 'table'  | ||||||
|  |                 AND name = 'notes_fts' | ||||||
|  |             `); | ||||||
|  |              | ||||||
|  |             this.isFTS5Available = result > 0; | ||||||
|  |              | ||||||
|  |             if (!this.isFTS5Available) { | ||||||
|  |                 log.info("FTS5 table not found. Full-text search will use fallback implementation."); | ||||||
|  |             } | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Error checking FTS5 availability: ${error}`); | ||||||
|  |             this.isFTS5Available = false; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         return this.isFTS5Available; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Converts Trilium search syntax to FTS5 MATCH syntax | ||||||
|  |      * | ||||||
|  |      * @param tokens - Array of search tokens | ||||||
|  |      * @param operator - Trilium search operator | ||||||
|  |      * @returns FTS5 MATCH query string | ||||||
|  |      */ | ||||||
|  |     convertToFTS5Query(tokens: string[], operator: string): string { | ||||||
|  |         if (!tokens || tokens.length === 0) { | ||||||
|  |             throw new Error("No search tokens provided"); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Substring operators (*=*, *=, =*) use LIKE queries now, not MATCH | ||||||
|  |         if (operator === "*=*" || operator === "*=" || operator === "=*") { | ||||||
|  |             throw new Error("Substring operators should use searchWithLike(), not MATCH queries"); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Trigram tokenizer requires minimum 3 characters | ||||||
|  |         const shortTokens = tokens.filter(token => token.length < 3); | ||||||
|  |         if (shortTokens.length > 0) { | ||||||
|  |             const shortList = shortTokens.join(', '); | ||||||
|  |             log.info(`Tokens shorter than 3 characters detected (${shortList}) - cannot use trigram FTS5`); | ||||||
|  |             throw new FTSNotAvailableError( | ||||||
|  |                 `Trigram tokenizer requires tokens of at least 3 characters. Short tokens: ${shortList}` | ||||||
|  |             ); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Sanitize tokens to prevent FTS5 syntax injection | ||||||
|  |         const sanitizedTokens = tokens.map(token => | ||||||
|  |             this.sanitizeFTS5Token(token) | ||||||
|  |         ); | ||||||
|  |  | ||||||
|  |         // Only handle operators that work with MATCH | ||||||
|  |         switch (operator) { | ||||||
|  |             case "=": // Exact phrase match | ||||||
|  |                 return `"${sanitizedTokens.join(" ")}"`; | ||||||
|  |  | ||||||
|  |             case "!=": // Does not contain | ||||||
|  |                 return `NOT (${sanitizedTokens.join(" OR ")})`; | ||||||
|  |  | ||||||
|  |             case "~=": // Fuzzy match (use OR) | ||||||
|  |             case "~*": | ||||||
|  |                 return sanitizedTokens.join(" OR "); | ||||||
|  |  | ||||||
|  |             case "%=": // Regex - fallback to custom function | ||||||
|  |                 log.error(`Regex search operator ${operator} not supported in FTS5`); | ||||||
|  |                 throw new FTSNotAvailableError("Regex search not supported in FTS5"); | ||||||
|  |  | ||||||
|  |             default: | ||||||
|  |                 throw new FTSQueryError(`Unsupported MATCH operator: ${operator}`); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Sanitizes a token for safe use in FTS5 queries | ||||||
|  |      * Validates that the token is not empty after sanitization | ||||||
|  |      */ | ||||||
|  |     private sanitizeFTS5Token(token: string): string { | ||||||
|  |         // Remove special FTS5 characters that could break syntax | ||||||
|  |         const sanitized = token | ||||||
|  |             .replace(/["\(\)\*]/g, '') // Remove quotes, parens, wildcards | ||||||
|  |             .replace(/\s+/g, ' ')       // Normalize whitespace | ||||||
|  |             .trim(); | ||||||
|  |  | ||||||
|  |         // Validate that token is not empty after sanitization | ||||||
|  |         if (!sanitized || sanitized.length === 0) { | ||||||
|  |             log.info(`Token became empty after sanitization: "${token}"`); | ||||||
|  |             // Return a safe placeholder that won't match anything | ||||||
|  |             return "__empty_token__"; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Additional validation: ensure token doesn't contain SQL injection attempts | ||||||
|  |         if (sanitized.includes(';') || sanitized.includes('--')) { | ||||||
|  |             log.error(`Potential SQL injection attempt detected in token: "${token}"`); | ||||||
|  |             return "__invalid_token__"; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         return sanitized; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Escapes LIKE wildcards (% and _) in user input to treat them as literals | ||||||
|  |      * @param str - User input string | ||||||
|  |      * @returns String with LIKE wildcards escaped | ||||||
|  |      */ | ||||||
|  |     private escapeLikeWildcards(str: string): string { | ||||||
|  |         return str.replace(/[%_]/g, '\\$&'); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Performs substring search using LIKE queries optimized by trigram index | ||||||
|  |      * This is used for *=*, *=, and =* operators with detail='none' | ||||||
|  |      * | ||||||
|  |      * @param tokens - Search tokens | ||||||
|  |      * @param operator - Search operator (*=*, *=, =*) | ||||||
|  |      * @param noteIds - Optional set of note IDs to filter | ||||||
|  |      * @param options - Search options | ||||||
|  |      * @param searchContext - Optional search context to track internal timing | ||||||
|  |      * @returns Array of search results (noteIds only, no scoring) | ||||||
|  |      */ | ||||||
|  |     searchWithLike( | ||||||
|  |         tokens: string[], | ||||||
|  |         operator: string, | ||||||
|  |         noteIds?: Set<string>, | ||||||
|  |         options: FTSSearchOptions = {}, | ||||||
|  |         searchContext?: any | ||||||
|  |     ): FTSSearchResult[] { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             throw new FTSNotAvailableError(); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Normalize tokens to lowercase for case-insensitive search | ||||||
|  |         const normalizedTokens = tokens.map(t => t.toLowerCase()); | ||||||
|  |  | ||||||
|  |         // Validate token lengths to prevent memory issues | ||||||
|  |         const MAX_TOKEN_LENGTH = 1000; | ||||||
|  |         const longTokens = normalizedTokens.filter(t => t.length > MAX_TOKEN_LENGTH); | ||||||
|  |         if (longTokens.length > 0) { | ||||||
|  |             throw new FTSQueryError( | ||||||
|  |                 `Search tokens too long (max ${MAX_TOKEN_LENGTH} characters). ` + | ||||||
|  |                 `Long tokens: ${longTokens.map(t => t.substring(0, 50) + '...').join(', ')}` | ||||||
|  |             ); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const { | ||||||
|  |             limit, // No default limit - return all results | ||||||
|  |             offset = 0, | ||||||
|  |             skipDiagnostics = false | ||||||
|  |         } = options; | ||||||
|  |  | ||||||
|  |         // Run diagnostics BEFORE the actual search (not counted in performance timing) | ||||||
|  |         if (!skipDiagnostics) { | ||||||
|  |             log.info('[FTS-DIAGNOSTICS] Running index completeness checks (not counted in search timing)...'); | ||||||
|  |             const totalInFts = sql.getValue<number>(`SELECT COUNT(*) FROM notes_fts`); | ||||||
|  |             const totalNotes = sql.getValue<number>(` | ||||||
|  |                 SELECT COUNT(*) | ||||||
|  |                 FROM notes n | ||||||
|  |                 LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                 WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                     AND n.isDeleted = 0 | ||||||
|  |                     AND n.isProtected = 0 | ||||||
|  |                     AND b.content IS NOT NULL | ||||||
|  |             `); | ||||||
|  |  | ||||||
|  |             if (totalInFts < totalNotes) { | ||||||
|  |                 log.warn(`[FTS-DIAGNOSTICS] FTS index incomplete: ${totalInFts} indexed out of ${totalNotes} total notes. Run syncMissingNotes().`); | ||||||
|  |             } else { | ||||||
|  |                 log.info(`[FTS-DIAGNOSTICS] FTS index complete: ${totalInFts} notes indexed`); | ||||||
|  |             } | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Start timing for actual search (excludes diagnostics) | ||||||
|  |             const searchStartTime = Date.now(); | ||||||
|  |  | ||||||
|  |             // Optimization: If noteIds set is very large, skip filtering to avoid expensive IN clauses | ||||||
|  |             // The FTS table already excludes protected notes, so we can search all notes | ||||||
|  |             const LARGE_SET_THRESHOLD = 1000; | ||||||
|  |             const isLargeNoteSet = noteIds && noteIds.size > LARGE_SET_THRESHOLD; | ||||||
|  |  | ||||||
|  |             if (isLargeNoteSet) { | ||||||
|  |                 log.info(`[FTS-OPTIMIZATION] Large noteIds set (${noteIds!.size} notes) - skipping IN clause filter, searching all FTS notes`); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Only filter noteIds if the set is small enough to benefit from it | ||||||
|  |             const shouldFilterByNoteIds = noteIds && noteIds.size > 0 && !isLargeNoteSet; | ||||||
|  |             const nonProtectedNoteIds = shouldFilterByNoteIds | ||||||
|  |                 ? this.filterNonProtectedNoteIds(noteIds) | ||||||
|  |                 : []; | ||||||
|  |  | ||||||
|  |             let whereConditions: string[] = []; | ||||||
|  |             const params: any[] = []; | ||||||
|  |  | ||||||
|  |             // Build LIKE conditions for each token - search BOTH title and content | ||||||
|  |             switch (operator) { | ||||||
|  |                 case "*=*": // Contains (substring) | ||||||
|  |                     normalizedTokens.forEach(token => { | ||||||
|  |                         // Search in BOTH title and content with escaped wildcards | ||||||
|  |                         whereConditions.push(`(title LIKE ? ESCAPE '\\' OR content LIKE ? ESCAPE '\\')`); | ||||||
|  |                         const escapedToken = this.escapeLikeWildcards(token); | ||||||
|  |                         params.push(`%${escapedToken}%`, `%${escapedToken}%`); | ||||||
|  |                     }); | ||||||
|  |                     break; | ||||||
|  |  | ||||||
|  |                 case "*=": // Ends with | ||||||
|  |                     normalizedTokens.forEach(token => { | ||||||
|  |                         whereConditions.push(`(title LIKE ? ESCAPE '\\' OR content LIKE ? ESCAPE '\\')`); | ||||||
|  |                         const escapedToken = this.escapeLikeWildcards(token); | ||||||
|  |                         params.push(`%${escapedToken}`, `%${escapedToken}`); | ||||||
|  |                     }); | ||||||
|  |                     break; | ||||||
|  |  | ||||||
|  |                 case "=*": // Starts with | ||||||
|  |                     normalizedTokens.forEach(token => { | ||||||
|  |                         whereConditions.push(`(title LIKE ? ESCAPE '\\' OR content LIKE ? ESCAPE '\\')`); | ||||||
|  |                         const escapedToken = this.escapeLikeWildcards(token); | ||||||
|  |                         params.push(`${escapedToken}%`, `${escapedToken}%`); | ||||||
|  |                     }); | ||||||
|  |                     break; | ||||||
|  |  | ||||||
|  |                 default: | ||||||
|  |                     throw new FTSQueryError(`Unsupported LIKE operator: ${operator}`); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Validate that we have search criteria | ||||||
|  |             if (whereConditions.length === 0 && nonProtectedNoteIds.length === 0) { | ||||||
|  |                 throw new FTSQueryError("No search criteria provided (empty tokens and no note filter)"); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // SQLite parameter limit handling (999 params max) | ||||||
|  |             const MAX_PARAMS_PER_QUERY = 900; // Leave margin for other params | ||||||
|  |  | ||||||
|  |             // Add noteId filter if provided | ||||||
|  |             if (nonProtectedNoteIds.length > 0) { | ||||||
|  |                 const tokenParamCount = params.length; | ||||||
|  |                 const additionalParams = 2; // For limit and offset | ||||||
|  |  | ||||||
|  |                 if (nonProtectedNoteIds.length <= MAX_PARAMS_PER_QUERY - tokenParamCount - additionalParams) { | ||||||
|  |                     // Normal case: all IDs fit in one query | ||||||
|  |                     whereConditions.push(`noteId IN (${nonProtectedNoteIds.map(() => '?').join(',')})`); | ||||||
|  |                     params.push(...nonProtectedNoteIds); | ||||||
|  |                 } else { | ||||||
|  |                     // Large noteIds set: split into chunks and execute multiple queries | ||||||
|  |                     const chunks: string[][] = []; | ||||||
|  |                     for (let i = 0; i < nonProtectedNoteIds.length; i += MAX_PARAMS_PER_QUERY) { | ||||||
|  |                         chunks.push(nonProtectedNoteIds.slice(i, i + MAX_PARAMS_PER_QUERY)); | ||||||
|  |                     } | ||||||
|  |  | ||||||
|  |                     log.info(`Large noteIds set detected (${nonProtectedNoteIds.length} notes), splitting into ${chunks.length} chunks`); | ||||||
|  |  | ||||||
|  |                     // Execute a query for each chunk and combine results | ||||||
|  |                     const allResults: FTSSearchResult[] = []; | ||||||
|  |                     let remainingLimit = limit !== undefined ? limit : Number.MAX_SAFE_INTEGER; | ||||||
|  |                     let currentOffset = offset; | ||||||
|  |  | ||||||
|  |                     for (const chunk of chunks) { | ||||||
|  |                         if (remainingLimit <= 0) break; | ||||||
|  |  | ||||||
|  |                         const chunkWhereConditions = [...whereConditions]; | ||||||
|  |                         const chunkParams: any[] = [...params]; | ||||||
|  |  | ||||||
|  |                         chunkWhereConditions.push(`noteId IN (${chunk.map(() => '?').join(',')})`); | ||||||
|  |                         chunkParams.push(...chunk); | ||||||
|  |  | ||||||
|  |                         // Build chunk query | ||||||
|  |                         const chunkQuery = ` | ||||||
|  |                             SELECT noteId, title | ||||||
|  |                             FROM notes_fts | ||||||
|  |                             WHERE ${chunkWhereConditions.join(' AND ')} | ||||||
|  |                             ${remainingLimit !== Number.MAX_SAFE_INTEGER ? 'LIMIT ?' : ''} | ||||||
|  |                             ${currentOffset > 0 ? 'OFFSET ?' : ''} | ||||||
|  |                         `; | ||||||
|  |  | ||||||
|  |                         if (remainingLimit !== Number.MAX_SAFE_INTEGER) chunkParams.push(remainingLimit); | ||||||
|  |                         if (currentOffset > 0) chunkParams.push(currentOffset); | ||||||
|  |  | ||||||
|  |                         const chunkResults = sql.getRows<{ noteId: string; title: string }>(chunkQuery, chunkParams); | ||||||
|  |                         allResults.push(...chunkResults.map(row => ({ | ||||||
|  |                             noteId: row.noteId, | ||||||
|  |                             title: row.title, | ||||||
|  |                             score: 1.0 | ||||||
|  |                         }))); | ||||||
|  |  | ||||||
|  |                         if (remainingLimit !== Number.MAX_SAFE_INTEGER) { | ||||||
|  |                             remainingLimit -= chunkResults.length; | ||||||
|  |                         } | ||||||
|  |                         currentOffset = 0; // Only apply offset to first chunk | ||||||
|  |                     } | ||||||
|  |  | ||||||
|  |                     const searchTime = Date.now() - searchStartTime; | ||||||
|  |                     log.info(`FTS5 LIKE search (chunked) returned ${allResults.length} results in ${searchTime}ms (excluding diagnostics)`); | ||||||
|  |  | ||||||
|  |                     // Track internal search time on context for performance comparison | ||||||
|  |                     if (searchContext) { | ||||||
|  |                         searchContext.ftsInternalSearchTime = searchTime; | ||||||
|  |                     } | ||||||
|  |  | ||||||
|  |                     return allResults; | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Build query - LIKE queries are automatically optimized by trigram index | ||||||
|  |             // Only add LIMIT/OFFSET if specified | ||||||
|  |             const query = ` | ||||||
|  |                 SELECT noteId, title | ||||||
|  |                 FROM notes_fts | ||||||
|  |                 WHERE ${whereConditions.join(' AND ')} | ||||||
|  |                 ${limit !== undefined ? 'LIMIT ?' : ''} | ||||||
|  |                 ${offset > 0 ? 'OFFSET ?' : ''} | ||||||
|  |             `; | ||||||
|  |  | ||||||
|  |             // Only add limit/offset params if specified | ||||||
|  |             if (limit !== undefined) params.push(limit); | ||||||
|  |             if (offset > 0) params.push(offset); | ||||||
|  |  | ||||||
|  |             // Log the search parameters | ||||||
|  |             log.info(`FTS5 LIKE search: tokens=[${normalizedTokens.join(', ')}], operator=${operator}, limit=${limit || 'none'}, offset=${offset}`); | ||||||
|  |  | ||||||
|  |             const rows = sql.getRows<{ noteId: string; title: string }>(query, params); | ||||||
|  |  | ||||||
|  |             const searchTime = Date.now() - searchStartTime; | ||||||
|  |             log.info(`FTS5 LIKE search returned ${rows.length} results in ${searchTime}ms (excluding diagnostics)`); | ||||||
|  |  | ||||||
|  |             // Track internal search time on context for performance comparison | ||||||
|  |             if (searchContext) { | ||||||
|  |                 searchContext.ftsInternalSearchTime = searchTime; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             return rows.map(row => ({ | ||||||
|  |                 noteId: row.noteId, | ||||||
|  |                 title: row.title, | ||||||
|  |                 score: 1.0 // LIKE queries don't have ranking | ||||||
|  |             })); | ||||||
|  |  | ||||||
|  |         } catch (error: any) { | ||||||
|  |             log.error(`FTS5 LIKE search error: ${error}`); | ||||||
|  |             throw new FTSQueryError( | ||||||
|  |                 `FTS5 LIKE search failed: ${error.message}`, | ||||||
|  |                 undefined | ||||||
|  |             ); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Performs a synchronous full-text search using FTS5 | ||||||
|  |      * | ||||||
|  |      * @param tokens - Search tokens | ||||||
|  |      * @param operator - Search operator | ||||||
|  |      * @param noteIds - Optional set of note IDs to search within | ||||||
|  |      * @param options - Search options | ||||||
|  |      * @param searchContext - Optional search context to track internal timing | ||||||
|  |      * @returns Array of search results | ||||||
|  |      */ | ||||||
|  |     searchSync( | ||||||
|  |         tokens: string[], | ||||||
|  |         operator: string, | ||||||
|  |         noteIds?: Set<string>, | ||||||
|  |         options: FTSSearchOptions = {}, | ||||||
|  |         searchContext?: any | ||||||
|  |     ): FTSSearchResult[] { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             throw new FTSNotAvailableError(); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const { | ||||||
|  |             limit = FTS_CONFIG.DEFAULT_LIMIT, | ||||||
|  |             offset = 0, | ||||||
|  |             includeSnippets = true, | ||||||
|  |             snippetLength = FTS_CONFIG.DEFAULT_SNIPPET_LENGTH, | ||||||
|  |             highlightTag = FTS_CONFIG.DEFAULT_HIGHLIGHT_START, | ||||||
|  |             searchProtected = false | ||||||
|  |         } = options; | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Start timing for actual search | ||||||
|  |             const searchStartTime = Date.now(); | ||||||
|  |  | ||||||
|  |             const ftsQuery = this.convertToFTS5Query(tokens, operator); | ||||||
|  |              | ||||||
|  |             // Validate query length | ||||||
|  |             if (ftsQuery.length > FTS_CONFIG.MAX_QUERY_LENGTH) { | ||||||
|  |                 throw new FTSQueryError( | ||||||
|  |                     `Query too long: ${ftsQuery.length} characters (max: ${FTS_CONFIG.MAX_QUERY_LENGTH})`, | ||||||
|  |                     ftsQuery | ||||||
|  |                 ); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Check if we're searching for protected notes | ||||||
|  |             // Protected notes are NOT in the FTS index, so we need to handle them separately | ||||||
|  |             if (searchProtected && protectedSessionService.isProtectedSessionAvailable()) { | ||||||
|  |                 log.info("Protected session available - will search protected notes separately"); | ||||||
|  |                 // Return empty results from FTS and let the caller handle protected notes | ||||||
|  |                 // The caller should use a fallback search method for protected notes | ||||||
|  |                 return []; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Build the SQL query | ||||||
|  |             let whereConditions = [`notes_fts MATCH ?`]; | ||||||
|  |             const params: any[] = [ftsQuery]; | ||||||
|  |  | ||||||
|  |             // Optimization: If noteIds set is very large, skip filtering to avoid expensive IN clauses | ||||||
|  |             // The FTS table already excludes protected notes, so we can search all notes | ||||||
|  |             const LARGE_SET_THRESHOLD = 1000; | ||||||
|  |             const isLargeNoteSet = noteIds && noteIds.size > LARGE_SET_THRESHOLD; | ||||||
|  |  | ||||||
|  |             if (isLargeNoteSet) { | ||||||
|  |                 log.info(`[FTS-OPTIMIZATION] Large noteIds set (${noteIds!.size} notes) - skipping IN clause filter, searching all FTS notes`); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Filter by noteIds if provided and set is small enough | ||||||
|  |             const shouldFilterByNoteIds = noteIds && noteIds.size > 0 && !isLargeNoteSet; | ||||||
|  |             if (shouldFilterByNoteIds) { | ||||||
|  |                 // First filter out any protected notes from the noteIds | ||||||
|  |                 const nonProtectedNoteIds = this.filterNonProtectedNoteIds(noteIds!); | ||||||
|  |                 if (nonProtectedNoteIds.length === 0) { | ||||||
|  |                     // All provided notes are protected, return empty results | ||||||
|  |                     return []; | ||||||
|  |                 } | ||||||
|  |                 whereConditions.push(`noteId IN (${nonProtectedNoteIds.map(() => '?').join(',')})`); | ||||||
|  |                 params.push(...nonProtectedNoteIds); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Build snippet extraction if requested | ||||||
|  |             const snippetSelect = includeSnippets  | ||||||
|  |                 ? `, snippet(notes_fts, ${FTS_CONFIG.SNIPPET_COLUMN_CONTENT}, '${highlightTag}', '${highlightTag.replace('<', '</')}', '...', ${snippetLength}) as snippet` | ||||||
|  |                 : ''; | ||||||
|  |  | ||||||
|  |             const query = ` | ||||||
|  |                 SELECT  | ||||||
|  |                     noteId, | ||||||
|  |                     title, | ||||||
|  |                     rank as score | ||||||
|  |                     ${snippetSelect} | ||||||
|  |                 FROM notes_fts | ||||||
|  |                 WHERE ${whereConditions.join(' AND ')} | ||||||
|  |                 ORDER BY rank | ||||||
|  |                 LIMIT ? OFFSET ? | ||||||
|  |             `; | ||||||
|  |  | ||||||
|  |             params.push(limit, offset); | ||||||
|  |  | ||||||
|  |             const results = sql.getRows<{ | ||||||
|  |                 noteId: string; | ||||||
|  |                 title: string; | ||||||
|  |                 score: number; | ||||||
|  |                 snippet?: string; | ||||||
|  |             }>(query, params); | ||||||
|  |  | ||||||
|  |             const searchTime = Date.now() - searchStartTime; | ||||||
|  |             log.info(`FTS5 MATCH search returned ${results.length} results in ${searchTime}ms`); | ||||||
|  |  | ||||||
|  |             // Track internal search time on context for performance comparison | ||||||
|  |             if (searchContext) { | ||||||
|  |                 searchContext.ftsInternalSearchTime = searchTime; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             return results; | ||||||
|  |  | ||||||
|  |         } catch (error: any) { | ||||||
|  |             // Provide structured error information | ||||||
|  |             if (error instanceof FTSError) { | ||||||
|  |                 throw error; | ||||||
|  |             } | ||||||
|  |              | ||||||
|  |             log.error(`FTS5 search error: ${error}`); | ||||||
|  |              | ||||||
|  |             // Determine if this is a recoverable error | ||||||
|  |             const isRecoverable =  | ||||||
|  |                 error.message?.includes('syntax error') || | ||||||
|  |                 error.message?.includes('malformed MATCH') || | ||||||
|  |                 error.message?.includes('no such table'); | ||||||
|  |              | ||||||
|  |             throw new FTSQueryError( | ||||||
|  |                 `FTS5 search failed: ${error.message}. ${isRecoverable ? 'Falling back to standard search.' : ''}`, | ||||||
|  |                 undefined | ||||||
|  |             ); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Filters out protected note IDs from the given set | ||||||
|  |      */ | ||||||
|  |     private filterNonProtectedNoteIds(noteIds: Set<string>): string[] { | ||||||
|  |         const noteIdList = Array.from(noteIds); | ||||||
|  |         const placeholders = noteIdList.map(() => '?').join(','); | ||||||
|  |          | ||||||
|  |         const nonProtectedNotes = sql.getColumn<string>(` | ||||||
|  |             SELECT noteId  | ||||||
|  |             FROM notes  | ||||||
|  |             WHERE noteId IN (${placeholders}) | ||||||
|  |                 AND isProtected = 0 | ||||||
|  |         `, noteIdList); | ||||||
|  |          | ||||||
|  |         return nonProtectedNotes; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Searches protected notes separately (not in FTS index) | ||||||
|  |      * This is a fallback method for protected notes | ||||||
|  |      */ | ||||||
|  |     searchProtectedNotesSync( | ||||||
|  |         tokens: string[], | ||||||
|  |         operator: string, | ||||||
|  |         noteIds?: Set<string>, | ||||||
|  |         options: FTSSearchOptions = {} | ||||||
|  |     ): FTSSearchResult[] { | ||||||
|  |         if (!protectedSessionService.isProtectedSessionAvailable()) { | ||||||
|  |             return []; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const { | ||||||
|  |             limit = FTS_CONFIG.DEFAULT_LIMIT, | ||||||
|  |             offset = 0 | ||||||
|  |         } = options; | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Build query for protected notes only | ||||||
|  |             let whereConditions = [`n.isProtected = 1`, `n.isDeleted = 0`]; | ||||||
|  |             const params: any[] = []; | ||||||
|  |  | ||||||
|  |             if (noteIds && noteIds.size > 0) { | ||||||
|  |                 const noteIdList = Array.from(noteIds); | ||||||
|  |                 whereConditions.push(`n.noteId IN (${noteIdList.map(() => '?').join(',')})`);   | ||||||
|  |                 params.push(...noteIdList); | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Get protected notes | ||||||
|  |             const protectedNotes = sql.getRows<{ | ||||||
|  |                 noteId: string; | ||||||
|  |                 title: string; | ||||||
|  |                 content: string | null; | ||||||
|  |             }>(` | ||||||
|  |                 SELECT n.noteId, n.title, b.content | ||||||
|  |                 FROM notes n | ||||||
|  |                 LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                 WHERE ${whereConditions.join(' AND ')} | ||||||
|  |                     AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                 LIMIT ? OFFSET ? | ||||||
|  |             `, [...params, limit, offset]); | ||||||
|  |  | ||||||
|  |             const results: FTSSearchResult[] = []; | ||||||
|  |  | ||||||
|  |             for (const note of protectedNotes) { | ||||||
|  |                 if (!note.content) continue; | ||||||
|  |  | ||||||
|  |                 try { | ||||||
|  |                     // Decrypt content | ||||||
|  |                     const decryptedContent = protectedSessionService.decryptString(note.content); | ||||||
|  |                     if (!decryptedContent) continue; | ||||||
|  |  | ||||||
|  |                     // Simple token matching for protected notes | ||||||
|  |                     const contentLower = decryptedContent.toLowerCase(); | ||||||
|  |                     const titleLower = note.title.toLowerCase(); | ||||||
|  |                     let matches = false; | ||||||
|  |  | ||||||
|  |                     switch (operator) { | ||||||
|  |                         case "=": // Exact match | ||||||
|  |                             const phrase = tokens.join(' ').toLowerCase(); | ||||||
|  |                             matches = contentLower.includes(phrase) || titleLower.includes(phrase); | ||||||
|  |                             break; | ||||||
|  |                         case "*=*": // Contains all tokens | ||||||
|  |                             matches = tokens.every(token =>  | ||||||
|  |                                 contentLower.includes(token.toLowerCase()) ||  | ||||||
|  |                                 titleLower.includes(token.toLowerCase()) | ||||||
|  |                             ); | ||||||
|  |                             break; | ||||||
|  |                         case "~=": // Contains any token | ||||||
|  |                         case "~*": | ||||||
|  |                             matches = tokens.some(token =>  | ||||||
|  |                                 contentLower.includes(token.toLowerCase()) ||  | ||||||
|  |                                 titleLower.includes(token.toLowerCase()) | ||||||
|  |                             ); | ||||||
|  |                             break; | ||||||
|  |                         default: | ||||||
|  |                             matches = tokens.every(token =>  | ||||||
|  |                                 contentLower.includes(token.toLowerCase()) ||  | ||||||
|  |                                 titleLower.includes(token.toLowerCase()) | ||||||
|  |                             ); | ||||||
|  |                     } | ||||||
|  |  | ||||||
|  |                     if (matches) { | ||||||
|  |                         results.push({ | ||||||
|  |                             noteId: note.noteId, | ||||||
|  |                             title: note.title, | ||||||
|  |                             score: 1.0, // Simple scoring for protected notes | ||||||
|  |                             snippet: this.generateSnippet(decryptedContent) | ||||||
|  |                         }); | ||||||
|  |                     } | ||||||
|  |                 } catch (error) { | ||||||
|  |                     log.info(`Could not decrypt protected note ${note.noteId}`); | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             return results; | ||||||
|  |         } catch (error: any) { | ||||||
|  |             log.error(`Protected notes search error: ${error}`); | ||||||
|  |             return []; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Generates a snippet from content | ||||||
|  |      */ | ||||||
|  |     private generateSnippet(content: string, maxLength: number = 30): string { | ||||||
|  |         // Strip HTML tags for snippet | ||||||
|  |         const plainText = striptags(content); | ||||||
|  |         const normalized = normalize(plainText); | ||||||
|  |          | ||||||
|  |         if (normalized.length <= maxLength * 10) { | ||||||
|  |             return normalized; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Extract snippet around first occurrence | ||||||
|  |         return normalized.substring(0, maxLength * 10) + '...'; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Updates the FTS index for a specific note (synchronous) | ||||||
|  |      *  | ||||||
|  |      * @param noteId - The note ID to update | ||||||
|  |      * @param title - The note title | ||||||
|  |      * @param content - The note content | ||||||
|  |      */ | ||||||
|  |     updateNoteIndex(noteId: string, title: string, content: string): void { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             return; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             sql.transactional(() => { | ||||||
|  |                 // Delete existing entry | ||||||
|  |                 sql.execute(`DELETE FROM notes_fts WHERE noteId = ?`, [noteId]); | ||||||
|  |                  | ||||||
|  |                 // Insert new entry | ||||||
|  |                 sql.execute(` | ||||||
|  |                     INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |                     VALUES (?, ?, ?) | ||||||
|  |                 `, [noteId, title, content]); | ||||||
|  |             }); | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Failed to update FTS index for note ${noteId}: ${error}`); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Removes a note from the FTS index (synchronous) | ||||||
|  |      *  | ||||||
|  |      * @param noteId - The note ID to remove | ||||||
|  |      */ | ||||||
|  |     removeNoteFromIndex(noteId: string): void { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             return; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             sql.execute(`DELETE FROM notes_fts WHERE noteId = ?`, [noteId]); | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Failed to remove note ${noteId} from FTS index: ${error}`); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Syncs missing notes to the FTS index (synchronous) | ||||||
|  |      * This is useful after bulk operations like imports where triggers might not fire | ||||||
|  |      *  | ||||||
|  |      * @param noteIds - Optional array of specific note IDs to sync. If not provided, syncs all missing notes. | ||||||
|  |      * @returns The number of notes that were synced | ||||||
|  |      */ | ||||||
|  |     syncMissingNotes(noteIds?: string[]): number { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             log.error("Cannot sync FTS index - FTS5 not available"); | ||||||
|  |             return 0; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             let syncedCount = 0; | ||||||
|  |              | ||||||
|  |             sql.transactional(() => { | ||||||
|  |                 let query: string; | ||||||
|  |                 let params: any[] = []; | ||||||
|  |                  | ||||||
|  |                 if (noteIds && noteIds.length > 0) { | ||||||
|  |                     // Sync specific notes that are missing from FTS | ||||||
|  |                     const placeholders = noteIds.map(() => '?').join(','); | ||||||
|  |                     query = ` | ||||||
|  |                         WITH missing_notes AS ( | ||||||
|  |                             SELECT  | ||||||
|  |                                 n.noteId, | ||||||
|  |                                 n.title, | ||||||
|  |                                 b.content | ||||||
|  |                             FROM notes n | ||||||
|  |                             LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                             WHERE n.noteId IN (${placeholders}) | ||||||
|  |                                 AND n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                                 AND n.isDeleted = 0 | ||||||
|  |                                 AND n.isProtected = 0 | ||||||
|  |                                 AND b.content IS NOT NULL | ||||||
|  |                                 AND NOT EXISTS (SELECT 1 FROM notes_fts WHERE noteId = n.noteId) | ||||||
|  |                         ) | ||||||
|  |                         INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |                         SELECT noteId, title, content FROM missing_notes | ||||||
|  |                     `; | ||||||
|  |                     params = noteIds; | ||||||
|  |                 } else { | ||||||
|  |                     // Sync all missing notes | ||||||
|  |                     query = ` | ||||||
|  |                         WITH missing_notes AS ( | ||||||
|  |                             SELECT  | ||||||
|  |                                 n.noteId, | ||||||
|  |                                 n.title, | ||||||
|  |                                 b.content | ||||||
|  |                             FROM notes n | ||||||
|  |                             LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                             WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                                 AND n.isDeleted = 0 | ||||||
|  |                                 AND n.isProtected = 0 | ||||||
|  |                                 AND b.content IS NOT NULL | ||||||
|  |                                 AND NOT EXISTS (SELECT 1 FROM notes_fts WHERE noteId = n.noteId) | ||||||
|  |                         ) | ||||||
|  |                         INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |                         SELECT noteId, title, content FROM missing_notes | ||||||
|  |                     `; | ||||||
|  |                 } | ||||||
|  |                  | ||||||
|  |                 const result = sql.execute(query, params); | ||||||
|  |                 syncedCount = result.changes; | ||||||
|  |                  | ||||||
|  |                 if (syncedCount > 0) { | ||||||
|  |                     log.info(`Synced ${syncedCount} missing notes to FTS index`); | ||||||
|  |                     // Optimize if we synced a significant number of notes | ||||||
|  |                     if (syncedCount > 100) { | ||||||
|  |                         sql.execute(`INSERT INTO notes_fts(notes_fts) VALUES('optimize')`); | ||||||
|  |                     } | ||||||
|  |                 } | ||||||
|  |             }); | ||||||
|  |              | ||||||
|  |             return syncedCount; | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Failed to sync missing notes to FTS index: ${error}`); | ||||||
|  |             return 0; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Rebuilds the entire FTS index (synchronous) | ||||||
|  |      * This is useful for maintenance or after bulk operations | ||||||
|  |      */ | ||||||
|  |     rebuildIndex(): void { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             log.error("Cannot rebuild FTS index - FTS5 not available"); | ||||||
|  |             return; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         log.info("Rebuilding FTS5 index..."); | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             sql.transactional(() => { | ||||||
|  |                 // Clear existing index | ||||||
|  |                 sql.execute(`DELETE FROM notes_fts`); | ||||||
|  |  | ||||||
|  |                 // Rebuild from notes | ||||||
|  |                 sql.execute(` | ||||||
|  |                     INSERT INTO notes_fts (noteId, title, content) | ||||||
|  |                     SELECT  | ||||||
|  |                         n.noteId, | ||||||
|  |                         n.title, | ||||||
|  |                         b.content | ||||||
|  |                     FROM notes n | ||||||
|  |                     LEFT JOIN blobs b ON n.blobId = b.blobId | ||||||
|  |                     WHERE n.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap') | ||||||
|  |                         AND n.isDeleted = 0 | ||||||
|  |                         AND n.isProtected = 0 | ||||||
|  |                 `); | ||||||
|  |  | ||||||
|  |                 // Optimize the FTS table | ||||||
|  |                 sql.execute(`INSERT INTO notes_fts(notes_fts) VALUES('optimize')`); | ||||||
|  |             }); | ||||||
|  |  | ||||||
|  |             log.info("FTS5 index rebuild completed"); | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Failed to rebuild FTS index: ${error}`); | ||||||
|  |             throw error; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Gets statistics about the FTS index (synchronous) | ||||||
|  |      * Includes fallback when dbstat is not available | ||||||
|  |      */ | ||||||
|  |     getIndexStats(): { | ||||||
|  |         totalDocuments: number; | ||||||
|  |         indexSize: number; | ||||||
|  |         isOptimized: boolean; | ||||||
|  |         dbstatAvailable: boolean; | ||||||
|  |     } { | ||||||
|  |         if (!this.checkFTS5Availability()) { | ||||||
|  |             return { | ||||||
|  |                 totalDocuments: 0, | ||||||
|  |                 indexSize: 0, | ||||||
|  |                 isOptimized: false, | ||||||
|  |                 dbstatAvailable: false | ||||||
|  |             }; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const totalDocuments = sql.getValue<number>(` | ||||||
|  |             SELECT COUNT(*) FROM notes_fts | ||||||
|  |         `) || 0; | ||||||
|  |  | ||||||
|  |         let indexSize = 0; | ||||||
|  |         let dbstatAvailable = false; | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Try to get index size from dbstat | ||||||
|  |             // dbstat is a virtual table that may not be available in all SQLite builds | ||||||
|  |             indexSize = sql.getValue<number>(` | ||||||
|  |                 SELECT SUM(pgsize)  | ||||||
|  |                 FROM dbstat  | ||||||
|  |                 WHERE name LIKE 'notes_fts%' | ||||||
|  |             `) || 0; | ||||||
|  |             dbstatAvailable = true; | ||||||
|  |         } catch (error: any) { | ||||||
|  |             // dbstat not available, use fallback | ||||||
|  |             if (error.message?.includes('no such table: dbstat')) { | ||||||
|  |                 log.info("dbstat virtual table not available, using fallback for index size estimation"); | ||||||
|  |                  | ||||||
|  |                 // Fallback: Estimate based on number of documents and average content size | ||||||
|  |                 try { | ||||||
|  |                     const avgContentSize = sql.getValue<number>(` | ||||||
|  |                         SELECT AVG(LENGTH(content) + LENGTH(title)) | ||||||
|  |                         FROM notes_fts | ||||||
|  |                         LIMIT 1000 | ||||||
|  |                     `) || 0; | ||||||
|  |                      | ||||||
|  |                     // Rough estimate: avg size * document count * overhead factor | ||||||
|  |                     indexSize = Math.round(avgContentSize * totalDocuments * 1.5); | ||||||
|  |                 } catch (fallbackError) { | ||||||
|  |                     log.info(`Could not estimate index size: ${fallbackError}`); | ||||||
|  |                     indexSize = 0; | ||||||
|  |                 } | ||||||
|  |             } else { | ||||||
|  |                 log.error(`Error accessing dbstat: ${error}`); | ||||||
|  |             } | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         return { | ||||||
|  |             totalDocuments, | ||||||
|  |             indexSize, | ||||||
|  |             isOptimized: true, // FTS5 manages optimization internally | ||||||
|  |             dbstatAvailable | ||||||
|  |         }; | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | // Export singleton instance | ||||||
|  | export const ftsSearchService = new FTSSearchService(); | ||||||
|  |  | ||||||
|  | export default ftsSearchService; | ||||||
| @@ -62,6 +62,10 @@ class NoteSet { | |||||||
|  |  | ||||||
|         return newNoteSet; |         return newNoteSet; | ||||||
|     } |     } | ||||||
|  |  | ||||||
|  |     getNoteIds(): Set<string> { | ||||||
|  |         return new Set(this.noteIdSet); | ||||||
|  |     } | ||||||
| } | } | ||||||
|  |  | ||||||
| export default NoteSet; | export default NoteSet; | ||||||
|   | |||||||
							
								
								
									
										178
									
								
								apps/server/src/services/search/performance_monitor.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										178
									
								
								apps/server/src/services/search/performance_monitor.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,178 @@ | |||||||
|  | /** | ||||||
|  |  * Performance monitoring utilities for search operations | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import log from "../log.js"; | ||||||
|  | import optionService from "../options.js"; | ||||||
|  |  | ||||||
|  | export interface SearchMetrics { | ||||||
|  |     query: string; | ||||||
|  |     backend: "typescript" | "sqlite"; | ||||||
|  |     totalTime: number; | ||||||
|  |     parseTime?: number; | ||||||
|  |     searchTime?: number; | ||||||
|  |     resultCount: number; | ||||||
|  |     memoryUsed?: number; | ||||||
|  |     cacheHit?: boolean; | ||||||
|  |     error?: string; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | export interface DetailedMetrics extends SearchMetrics { | ||||||
|  |     phases?: { | ||||||
|  |         name: string; | ||||||
|  |         duration: number; | ||||||
|  |     }[]; | ||||||
|  |     sqliteStats?: { | ||||||
|  |         rowsScanned?: number; | ||||||
|  |         indexUsed?: boolean; | ||||||
|  |         tempBTreeUsed?: boolean; | ||||||
|  |     }; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | interface SearchPerformanceAverages { | ||||||
|  |     avgTime: number; | ||||||
|  |     avgResults: number; | ||||||
|  |     totalQueries: number; | ||||||
|  |     errorRate: number; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | class PerformanceMonitor { | ||||||
|  |     private metrics: SearchMetrics[] = []; | ||||||
|  |     private maxMetricsStored = 1000; | ||||||
|  |     private metricsEnabled = false; | ||||||
|  |  | ||||||
|  |     constructor() { | ||||||
|  |         // Check if performance logging is enabled | ||||||
|  |         this.updateSettings(); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     updateSettings() { | ||||||
|  |         try { | ||||||
|  |             this.metricsEnabled = optionService.getOptionBool("searchSqlitePerformanceLogging"); | ||||||
|  |         } catch { | ||||||
|  |             this.metricsEnabled = false; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     startTimer(): () => number { | ||||||
|  |         const startTime = process.hrtime.bigint(); | ||||||
|  |         return () => { | ||||||
|  |             const endTime = process.hrtime.bigint(); | ||||||
|  |             return Number(endTime - startTime) / 1_000_000; // Convert to milliseconds | ||||||
|  |         }; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     recordMetrics(metrics: SearchMetrics) { | ||||||
|  |         if (!this.metricsEnabled) { | ||||||
|  |             return; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         this.metrics.push(metrics); | ||||||
|  |  | ||||||
|  |         // Keep only the last N metrics | ||||||
|  |         if (this.metrics.length > this.maxMetricsStored) { | ||||||
|  |             this.metrics = this.metrics.slice(-this.maxMetricsStored); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Log significant performance differences | ||||||
|  |         if (metrics.totalTime > 1000) { | ||||||
|  |             log.info(`Slow search query detected: ${metrics.totalTime.toFixed(2)}ms for query "${metrics.query.substring(0, 100)}"`); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Log to debug for analysis | ||||||
|  |         log.info(`Search metrics: backend=${metrics.backend}, time=${metrics.totalTime.toFixed(2)}ms, results=${metrics.resultCount}, query="${metrics.query.substring(0, 50)}"`); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     recordDetailedMetrics(metrics: DetailedMetrics) { | ||||||
|  |         if (!this.metricsEnabled) { | ||||||
|  |             return; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         this.recordMetrics(metrics); | ||||||
|  |  | ||||||
|  |         // Log detailed phase information | ||||||
|  |         if (metrics.phases) { | ||||||
|  |             const phaseLog = metrics.phases | ||||||
|  |                 .map(p => `${p.name}=${p.duration.toFixed(2)}ms`) | ||||||
|  |                 .join(", "); | ||||||
|  |             log.info(`Search phases: ${phaseLog}`); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Log SQLite specific stats | ||||||
|  |         if (metrics.sqliteStats) { | ||||||
|  |             log.info(`SQLite stats: rows_scanned=${metrics.sqliteStats.rowsScanned}, index_used=${metrics.sqliteStats.indexUsed}`); | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     getRecentMetrics(count: number = 100): SearchMetrics[] { | ||||||
|  |         return this.metrics.slice(-count); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     getAverageMetrics(backend?: "typescript" | "sqlite"): SearchPerformanceAverages | null { | ||||||
|  |         let relevantMetrics = this.metrics; | ||||||
|  |          | ||||||
|  |         if (backend) { | ||||||
|  |             relevantMetrics = this.metrics.filter(m => m.backend === backend); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         if (relevantMetrics.length === 0) { | ||||||
|  |             return null; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const totalTime = relevantMetrics.reduce((sum, m) => sum + m.totalTime, 0); | ||||||
|  |         const totalResults = relevantMetrics.reduce((sum, m) => sum + m.resultCount, 0); | ||||||
|  |         const errorCount = relevantMetrics.filter(m => m.error).length; | ||||||
|  |  | ||||||
|  |         return { | ||||||
|  |             avgTime: totalTime / relevantMetrics.length, | ||||||
|  |             avgResults: totalResults / relevantMetrics.length, | ||||||
|  |             totalQueries: relevantMetrics.length, | ||||||
|  |             errorRate: errorCount / relevantMetrics.length | ||||||
|  |         }; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     compareBackends(): { | ||||||
|  |         typescript: SearchPerformanceAverages; | ||||||
|  |         sqlite: SearchPerformanceAverages; | ||||||
|  |         recommendation?: string; | ||||||
|  |     } { | ||||||
|  |         const tsMetrics = this.getAverageMetrics("typescript"); | ||||||
|  |         const sqliteMetrics = this.getAverageMetrics("sqlite"); | ||||||
|  |  | ||||||
|  |         let recommendation: string | undefined; | ||||||
|  |  | ||||||
|  |         if (tsMetrics && sqliteMetrics) { | ||||||
|  |             const speedupFactor = tsMetrics.avgTime / sqliteMetrics.avgTime; | ||||||
|  |              | ||||||
|  |             if (speedupFactor > 1.5) { | ||||||
|  |                 recommendation = `SQLite is ${speedupFactor.toFixed(1)}x faster on average`; | ||||||
|  |             } else if (speedupFactor < 0.67) { | ||||||
|  |                 recommendation = `TypeScript is ${(1/speedupFactor).toFixed(1)}x faster on average`; | ||||||
|  |             } else { | ||||||
|  |                 recommendation = "Both backends perform similarly"; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Consider error rates | ||||||
|  |             if (sqliteMetrics.errorRate > tsMetrics.errorRate + 0.1) { | ||||||
|  |                 recommendation += " (but SQLite has higher error rate)"; | ||||||
|  |             } else if (tsMetrics.errorRate > sqliteMetrics.errorRate + 0.1) { | ||||||
|  |                 recommendation += " (but TypeScript has higher error rate)"; | ||||||
|  |             } | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         return { | ||||||
|  |             typescript: tsMetrics || { avgTime: 0, avgResults: 0, totalQueries: 0, errorRate: 0 }, | ||||||
|  |             sqlite: sqliteMetrics || { avgTime: 0, avgResults: 0, totalQueries: 0, errorRate: 0 }, | ||||||
|  |             recommendation | ||||||
|  |         }; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     reset() { | ||||||
|  |         this.metrics = []; | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | // Singleton instance | ||||||
|  | const performanceMonitor = new PerformanceMonitor(); | ||||||
|  |  | ||||||
|  | export default performanceMonitor; | ||||||
| @@ -24,6 +24,7 @@ class SearchContext { | |||||||
|     fulltextQuery: string; |     fulltextQuery: string; | ||||||
|     dbLoadNeeded: boolean; |     dbLoadNeeded: boolean; | ||||||
|     error: string | null; |     error: string | null; | ||||||
|  |     ftsInternalSearchTime: number | null; // Time spent in actual FTS search (excluding diagnostics) | ||||||
|  |  | ||||||
|     constructor(params: SearchParams = {}) { |     constructor(params: SearchParams = {}) { | ||||||
|         this.fastSearch = !!params.fastSearch; |         this.fastSearch = !!params.fastSearch; | ||||||
| @@ -54,6 +55,7 @@ class SearchContext { | |||||||
|         // and some extra data needs to be loaded before executing |         // and some extra data needs to be loaded before executing | ||||||
|         this.dbLoadNeeded = false; |         this.dbLoadNeeded = false; | ||||||
|         this.error = null; |         this.error = null; | ||||||
|  |         this.ftsInternalSearchTime = null; | ||||||
|     } |     } | ||||||
|  |  | ||||||
|     addError(error: string) { |     addError(error: string) { | ||||||
|   | |||||||
| @@ -19,6 +19,7 @@ import sql from "../../sql.js"; | |||||||
| import scriptService from "../../script.js"; | import scriptService from "../../script.js"; | ||||||
| import striptags from "striptags"; | import striptags from "striptags"; | ||||||
| import protectedSessionService from "../../protected_session.js"; | import protectedSessionService from "../../protected_session.js"; | ||||||
|  | import ftsSearchService from "../fts_search.js"; | ||||||
|  |  | ||||||
| export interface SearchNoteResult { | export interface SearchNoteResult { | ||||||
|     searchResultNoteIds: string[]; |     searchResultNoteIds: string[]; | ||||||
| @@ -401,7 +402,8 @@ function parseQueryToExpression(query: string, searchContext: SearchContext) { | |||||||
| } | } | ||||||
|  |  | ||||||
| function searchNotes(query: string, params: SearchParams = {}): BNote[] { | function searchNotes(query: string, params: SearchParams = {}): BNote[] { | ||||||
|     const searchResults = findResultsWithQuery(query, new SearchContext(params)); |     const searchContext = new SearchContext(params); | ||||||
|  |     const searchResults = findResultsWithQuery(query, searchContext); | ||||||
|  |  | ||||||
|     return searchResults.map((sr) => becca.notes[sr.noteId]); |     return searchResults.map((sr) => becca.notes[sr.noteId]); | ||||||
| } | } | ||||||
| @@ -421,12 +423,86 @@ function findResultsWithQuery(query: string, searchContext: SearchContext): Sear | |||||||
|     // ordering or other logic that shouldn't be interfered with. |     // ordering or other logic that shouldn't be interfered with. | ||||||
|     const isPureExpressionQuery = query.trim().startsWith('#'); |     const isPureExpressionQuery = query.trim().startsWith('#'); | ||||||
|  |  | ||||||
|  |     // Performance comparison for quick-search (fastSearch === false) | ||||||
|  |     const isQuickSearch = searchContext.fastSearch === false; | ||||||
|  |     let results: SearchResult[]; | ||||||
|  |     let ftsTime = 0; | ||||||
|  |     let traditionalTime = 0; | ||||||
|  |  | ||||||
|     if (isPureExpressionQuery) { |     if (isPureExpressionQuery) { | ||||||
|         // For pure expression queries, use standard search without progressive phases |         // For pure expression queries, use standard search without progressive phases | ||||||
|         return performSearch(expression, searchContext, searchContext.enableFuzzyMatching); |         results = performSearch(expression, searchContext, searchContext.enableFuzzyMatching); | ||||||
|  |     } else { | ||||||
|  |         // For quick-search, run both FTS5 and traditional search to compare | ||||||
|  |         if (isQuickSearch) { | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] Starting comparison for query: "${query}"`); | ||||||
|  |  | ||||||
|  |             // Time FTS5 search (normal path) | ||||||
|  |             const ftsStartTime = Date.now(); | ||||||
|  |             results = findResultsWithExpression(expression, searchContext); | ||||||
|  |             ftsTime = Date.now() - ftsStartTime; | ||||||
|  |  | ||||||
|  |             // Time traditional search (with FTS5 disabled) | ||||||
|  |             const traditionalStartTime = Date.now(); | ||||||
|  |  | ||||||
|  |             // Create a new search context with FTS5 disabled | ||||||
|  |             const traditionalContext = new SearchContext({ | ||||||
|  |                 fastSearch: false, | ||||||
|  |                 includeArchivedNotes: false, | ||||||
|  |                 includeHiddenNotes: true, | ||||||
|  |                 fuzzyAttributeSearch: true, | ||||||
|  |                 ignoreInternalAttributes: true, | ||||||
|  |                 ancestorNoteId: searchContext.ancestorNoteId | ||||||
|  |             }); | ||||||
|  |  | ||||||
|  |             // Temporarily disable FTS5 to force traditional search | ||||||
|  |             const originalFtsAvailable = (ftsSearchService as any).isFTS5Available; | ||||||
|  |             (ftsSearchService as any).isFTS5Available = false; | ||||||
|  |  | ||||||
|  |             const traditionalResults = findResultsWithExpression(expression, traditionalContext); | ||||||
|  |             traditionalTime = Date.now() - traditionalStartTime; | ||||||
|  |  | ||||||
|  |             // Restore FTS5 availability | ||||||
|  |             (ftsSearchService as any).isFTS5Available = originalFtsAvailable; | ||||||
|  |  | ||||||
|  |             // Log performance comparison | ||||||
|  |             // Use internal FTS search time (excluding diagnostics) if available | ||||||
|  |             const ftsInternalTime = searchContext.ftsInternalSearchTime ?? ftsTime; | ||||||
|  |             const speedup = traditionalTime > 0 ? (traditionalTime / ftsInternalTime).toFixed(2) : "N/A"; | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] ===== Results for query: "${query}" =====`); | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] FTS5 search: ${ftsInternalTime}ms (excluding diagnostics), found ${results.length} results`); | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] Traditional search: ${traditionalTime}ms, found ${traditionalResults.length} results`); | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] FTS5 is ${speedup}x faster (saved ${traditionalTime - ftsInternalTime}ms)`); | ||||||
|  |  | ||||||
|  |             // Check if results match | ||||||
|  |             const ftsNoteIds = new Set(results.map(r => r.noteId)); | ||||||
|  |             const traditionalNoteIds = new Set(traditionalResults.map(r => r.noteId)); | ||||||
|  |             const matchingResults = ftsNoteIds.size === traditionalNoteIds.size && | ||||||
|  |                                   Array.from(ftsNoteIds).every(id => traditionalNoteIds.has(id)); | ||||||
|  |  | ||||||
|  |             if (!matchingResults) { | ||||||
|  |                 log.info(`[QUICK-SEARCH-COMPARISON] Results differ! FTS5: ${ftsNoteIds.size} notes, Traditional: ${traditionalNoteIds.size} notes`); | ||||||
|  |  | ||||||
|  |                 // Find differences | ||||||
|  |                 const onlyInFTS = Array.from(ftsNoteIds).filter(id => !traditionalNoteIds.has(id)); | ||||||
|  |                 const onlyInTraditional = Array.from(traditionalNoteIds).filter(id => !ftsNoteIds.has(id)); | ||||||
|  |  | ||||||
|  |                 if (onlyInFTS.length > 0) { | ||||||
|  |                     log.info(`[QUICK-SEARCH-COMPARISON] Only in FTS5: ${onlyInFTS.slice(0, 5).join(", ")}${onlyInFTS.length > 5 ? "..." : ""}`); | ||||||
|  |                 } | ||||||
|  |                 if (onlyInTraditional.length > 0) { | ||||||
|  |                     log.info(`[QUICK-SEARCH-COMPARISON] Only in Traditional: ${onlyInTraditional.slice(0, 5).join(", ")}${onlyInTraditional.length > 5 ? "..." : ""}`); | ||||||
|  |                 } | ||||||
|  |             } else { | ||||||
|  |                 log.info(`[QUICK-SEARCH-COMPARISON] Results match perfectly! ✓`); | ||||||
|  |             } | ||||||
|  |             log.info(`[QUICK-SEARCH-COMPARISON] ========================================`); | ||||||
|  |         } else { | ||||||
|  |             results = findResultsWithExpression(expression, searchContext); | ||||||
|  |         } | ||||||
|     } |     } | ||||||
|  |  | ||||||
|     return findResultsWithExpression(expression, searchContext); |     return results; | ||||||
| } | } | ||||||
|  |  | ||||||
| function findFirstNoteWithQuery(query: string, searchContext: SearchContext): BNote | null { | function findFirstNoteWithQuery(query: string, searchContext: SearchContext): BNote | null { | ||||||
|   | |||||||
							
								
								
									
										113
									
								
								apps/server/src/services/search/sqlite_functions.spec.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										113
									
								
								apps/server/src/services/search/sqlite_functions.spec.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,113 @@ | |||||||
|  | /** | ||||||
|  |  * Tests for SQLite custom functions service | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import { describe, it, expect, beforeEach, afterEach } from 'vitest'; | ||||||
|  | import Database from 'better-sqlite3'; | ||||||
|  | import { SqliteFunctionsService, getSqliteFunctionsService } from './sqlite_functions.js'; | ||||||
|  |  | ||||||
|  | describe('SqliteFunctionsService', () => { | ||||||
|  |     let db: Database.Database; | ||||||
|  |     let service: SqliteFunctionsService; | ||||||
|  |  | ||||||
|  |     beforeEach(() => { | ||||||
|  |         // Create in-memory database for testing | ||||||
|  |         db = new Database(':memory:'); | ||||||
|  |         service = getSqliteFunctionsService(); | ||||||
|  |         // Reset registration state | ||||||
|  |         service.unregister(); | ||||||
|  |     }); | ||||||
|  |  | ||||||
|  |     afterEach(() => { | ||||||
|  |         db.close(); | ||||||
|  |     }); | ||||||
|  |  | ||||||
|  |     describe('Service Registration', () => { | ||||||
|  |         it('should register functions successfully', () => { | ||||||
|  |             const result = service.registerFunctions(db); | ||||||
|  |             expect(result).toBe(true); | ||||||
|  |             expect(service.isRegistered()).toBe(true); | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should not re-register if already registered', () => { | ||||||
|  |             service.registerFunctions(db); | ||||||
|  |             const result = service.registerFunctions(db); | ||||||
|  |             expect(result).toBe(true); // Still returns true but doesn't re-register | ||||||
|  |             expect(service.isRegistered()).toBe(true); | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should handle registration errors gracefully', () => { | ||||||
|  |             // Close the database to cause registration to fail | ||||||
|  |             db.close(); | ||||||
|  |             const result = service.registerFunctions(db); | ||||||
|  |             expect(result).toBe(false); | ||||||
|  |             expect(service.isRegistered()).toBe(false); | ||||||
|  |         }); | ||||||
|  |     }); | ||||||
|  |  | ||||||
|  |     describe('edit_distance function', () => { | ||||||
|  |         beforeEach(() => { | ||||||
|  |             service.registerFunctions(db); | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should calculate edit distance correctly', () => { | ||||||
|  |             const tests = [ | ||||||
|  |                 ['hello', 'hello', 0], | ||||||
|  |                 ['hello', 'hallo', 1], | ||||||
|  |                 ['hello', 'help', 2], | ||||||
|  |                 ['hello', 'world', 4], | ||||||
|  |                 ['', '', 0], | ||||||
|  |                 ['abc', '', 3], | ||||||
|  |                 ['', 'abc', 3], | ||||||
|  |             ]; | ||||||
|  |  | ||||||
|  |             for (const [str1, str2, expected] of tests) { | ||||||
|  |                 const result = db.prepare('SELECT edit_distance(?, ?, 5) as distance').get(str1, str2) as any; | ||||||
|  |                 expect(result.distance).toBe((expected as number) <= 5 ? (expected as number) : 6); | ||||||
|  |             } | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should respect max distance threshold', () => { | ||||||
|  |             const result = db.prepare('SELECT edit_distance(?, ?, ?) as distance') | ||||||
|  |                 .get('hello', 'world', 2) as any; | ||||||
|  |             expect(result.distance).toBe(3); // Returns maxDistance + 1 when exceeded | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should handle null inputs', () => { | ||||||
|  |             const result = db.prepare('SELECT edit_distance(?, ?, 2) as distance').get(null, 'test') as any; | ||||||
|  |             expect(result.distance).toBe(3); // Treats null as empty string, distance exceeds max | ||||||
|  |         }); | ||||||
|  |     }); | ||||||
|  |  | ||||||
|  |     describe('regex_match function', () => { | ||||||
|  |         beforeEach(() => { | ||||||
|  |             service.registerFunctions(db); | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should match regex patterns correctly', () => { | ||||||
|  |             const tests = [ | ||||||
|  |                 ['hello world', 'hello', 1], | ||||||
|  |                 ['hello world', 'HELLO', 1], // Case insensitive by default | ||||||
|  |                 ['hello world', '^hello', 1], | ||||||
|  |                 ['hello world', 'world$', 1], | ||||||
|  |                 ['hello world', 'foo', 0], | ||||||
|  |                 ['test@example.com', '\\w+@\\w+\\.\\w+', 1], | ||||||
|  |             ]; | ||||||
|  |  | ||||||
|  |             for (const [text, pattern, expected] of tests) { | ||||||
|  |                 const result = db.prepare("SELECT regex_match(?, ?, 'i') as match").get(text, pattern) as any; | ||||||
|  |                 expect(result.match).toBe(expected); | ||||||
|  |             } | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should handle invalid regex gracefully', () => { | ||||||
|  |             const result = db.prepare("SELECT regex_match(?, ?, 'i') as match").get('test', '[invalid') as any; | ||||||
|  |             expect(result.match).toBe(null); // Returns null for invalid regex | ||||||
|  |         }); | ||||||
|  |  | ||||||
|  |         it('should handle null inputs', () => { | ||||||
|  |             const result = db.prepare("SELECT regex_match(?, ?, 'i') as match").get(null, 'test') as any; | ||||||
|  |             expect(result.match).toBe(0); | ||||||
|  |         }); | ||||||
|  |     }); | ||||||
|  | }); | ||||||
							
								
								
									
										284
									
								
								apps/server/src/services/search/sqlite_functions.ts
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										284
									
								
								apps/server/src/services/search/sqlite_functions.ts
									
									
									
									
									
										Normal file
									
								
							| @@ -0,0 +1,284 @@ | |||||||
|  | /** | ||||||
|  |  * SQLite Custom Functions Service | ||||||
|  |  * | ||||||
|  |  * This service manages custom SQLite functions for general database operations. | ||||||
|  |  * Functions are registered with better-sqlite3 to provide native-speed operations | ||||||
|  |  * directly within SQL queries. | ||||||
|  |  * | ||||||
|  |  * These functions are used by: | ||||||
|  |  * - Fuzzy search fallback (edit_distance) | ||||||
|  |  * - Regular expression matching (regex_match) | ||||||
|  |  */ | ||||||
|  |  | ||||||
|  | import type { Database } from "better-sqlite3"; | ||||||
|  | import log from "../log.js"; | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Configuration for fuzzy search operations | ||||||
|  |  */ | ||||||
|  | const FUZZY_CONFIG = { | ||||||
|  |     MAX_EDIT_DISTANCE: 2, | ||||||
|  |     MIN_TOKEN_LENGTH: 3, | ||||||
|  |     MAX_STRING_LENGTH: 1000, // Performance guard for edit distance | ||||||
|  | } as const; | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Interface for registering a custom SQL function | ||||||
|  |  */ | ||||||
|  | interface SQLiteFunction { | ||||||
|  |     name: string; | ||||||
|  |     implementation: (...args: any[]) => any; | ||||||
|  |     options?: { | ||||||
|  |         deterministic?: boolean; | ||||||
|  |         varargs?: boolean; | ||||||
|  |         directOnly?: boolean; | ||||||
|  |     }; | ||||||
|  | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Manages registration and lifecycle of custom SQLite functions | ||||||
|  |  */ | ||||||
|  | export class SqliteFunctionsService { | ||||||
|  |     private static instance: SqliteFunctionsService | null = null; | ||||||
|  |     private registered = false; | ||||||
|  |     private functions: SQLiteFunction[] = []; | ||||||
|  |  | ||||||
|  |     private constructor() { | ||||||
|  |         // Initialize the function definitions | ||||||
|  |         this.initializeFunctions(); | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Get singleton instance of the service | ||||||
|  |      */ | ||||||
|  |     static getInstance(): SqliteFunctionsService { | ||||||
|  |         if (!SqliteFunctionsService.instance) { | ||||||
|  |             SqliteFunctionsService.instance = new SqliteFunctionsService(); | ||||||
|  |         } | ||||||
|  |         return SqliteFunctionsService.instance; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Initialize all custom function definitions | ||||||
|  |      */ | ||||||
|  |     private initializeFunctions(): void { | ||||||
|  |         // Bind all methods to preserve 'this' context | ||||||
|  |         this.functions = [ | ||||||
|  |             { | ||||||
|  |                 name: "edit_distance", | ||||||
|  |                 implementation: this.editDistance.bind(this), | ||||||
|  |                 options: { | ||||||
|  |                     deterministic: true, | ||||||
|  |                     varargs: true  // Changed to true to handle variable arguments | ||||||
|  |                 } | ||||||
|  |             }, | ||||||
|  |             { | ||||||
|  |                 name: "regex_match", | ||||||
|  |                 implementation: this.regexMatch.bind(this), | ||||||
|  |                 options: { | ||||||
|  |                     deterministic: true, | ||||||
|  |                     varargs: true  // Changed to true to handle variable arguments | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |         ]; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Register all custom functions with the database connection | ||||||
|  |      *  | ||||||
|  |      * @param db The better-sqlite3 database connection | ||||||
|  |      * @returns true if registration was successful, false otherwise | ||||||
|  |      */ | ||||||
|  |     registerFunctions(db: Database): boolean { | ||||||
|  |         if (this.registered) { | ||||||
|  |             log.info("SQLite custom functions already registered"); | ||||||
|  |             return true; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Test if the database connection is valid first | ||||||
|  |             // This will throw if the database is closed | ||||||
|  |             db.pragma("user_version"); | ||||||
|  |              | ||||||
|  |             log.info("Registering SQLite custom functions..."); | ||||||
|  |              | ||||||
|  |             let successCount = 0; | ||||||
|  |             for (const func of this.functions) { | ||||||
|  |                 try { | ||||||
|  |                     db.function(func.name, func.options || {}, func.implementation); | ||||||
|  |                     log.info(`Registered SQLite function: ${func.name}`); | ||||||
|  |                     successCount++; | ||||||
|  |                 } catch (error) { | ||||||
|  |                     log.error(`Failed to register SQLite function ${func.name}: ${error}`); | ||||||
|  |                     // Continue registering other functions even if one fails | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Only mark as registered if at least some functions were registered | ||||||
|  |             if (successCount > 0) { | ||||||
|  |                 this.registered = true; | ||||||
|  |                 log.info(`SQLite custom functions registration completed (${successCount}/${this.functions.length})`); | ||||||
|  |                 return true; | ||||||
|  |             } else { | ||||||
|  |                 log.error("No SQLite functions could be registered"); | ||||||
|  |                 return false; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |         } catch (error) { | ||||||
|  |             log.error(`Failed to register SQLite custom functions: ${error}`); | ||||||
|  |             return false; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Unregister all custom functions (for cleanup/testing) | ||||||
|  |      * Note: better-sqlite3 doesn't provide a way to unregister functions, | ||||||
|  |      * so this just resets the internal state | ||||||
|  |      */ | ||||||
|  |     unregister(): void { | ||||||
|  |         this.registered = false; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Check if functions are currently registered | ||||||
|  |      */ | ||||||
|  |     isRegistered(): boolean { | ||||||
|  |         return this.registered; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     // ===== Function Implementations ===== | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Calculate Levenshtein edit distance between two strings | ||||||
|  |      * Optimized with early termination and single-array approach | ||||||
|  |      *  | ||||||
|  |      * SQLite will pass 2 or 3 arguments: | ||||||
|  |      * - 2 args: str1, str2 (uses default maxDistance) | ||||||
|  |      * - 3 args: str1, str2, maxDistance | ||||||
|  |      *  | ||||||
|  |      * @returns Edit distance or maxDistance + 1 if exceeded | ||||||
|  |      */ | ||||||
|  |     private editDistance(...args: any[]): number { | ||||||
|  |         // Handle variable arguments from SQLite | ||||||
|  |         let str1: string | null | undefined = args[0]; | ||||||
|  |         let str2: string | null | undefined = args[1]; | ||||||
|  |         let maxDistance: number = args.length > 2 ? args[2] : FUZZY_CONFIG.MAX_EDIT_DISTANCE; | ||||||
|  |         // Handle null/undefined inputs | ||||||
|  |         if (!str1 || typeof str1 !== 'string') str1 = ''; | ||||||
|  |         if (!str2 || typeof str2 !== 'string') str2 = ''; | ||||||
|  |          | ||||||
|  |         // Validate and sanitize maxDistance | ||||||
|  |         if (typeof maxDistance !== 'number' || !Number.isFinite(maxDistance)) { | ||||||
|  |             maxDistance = FUZZY_CONFIG.MAX_EDIT_DISTANCE; | ||||||
|  |         } else { | ||||||
|  |             // Ensure it's a positive integer | ||||||
|  |             maxDistance = Math.max(0, Math.floor(maxDistance)); | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const len1 = str1.length; | ||||||
|  |         const len2 = str2.length; | ||||||
|  |  | ||||||
|  |         // Performance guard for very long strings | ||||||
|  |         if (len1 > FUZZY_CONFIG.MAX_STRING_LENGTH || len2 > FUZZY_CONFIG.MAX_STRING_LENGTH) { | ||||||
|  |             return Math.abs(len1 - len2) <= maxDistance ? Math.abs(len1 - len2) : maxDistance + 1; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Early termination: length difference exceeds max | ||||||
|  |         if (Math.abs(len1 - len2) > maxDistance) { | ||||||
|  |             return maxDistance + 1; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         // Handle edge cases | ||||||
|  |         if (len1 === 0) return len2 <= maxDistance ? len2 : maxDistance + 1; | ||||||
|  |         if (len2 === 0) return len1 <= maxDistance ? len1 : maxDistance + 1; | ||||||
|  |  | ||||||
|  |         // Single-array optimization for memory efficiency | ||||||
|  |         let previousRow = Array.from({ length: len2 + 1 }, (_, i) => i); | ||||||
|  |         let currentRow = new Array(len2 + 1); | ||||||
|  |  | ||||||
|  |         for (let i = 1; i <= len1; i++) { | ||||||
|  |             currentRow[0] = i; | ||||||
|  |             let minInRow = i; | ||||||
|  |  | ||||||
|  |             for (let j = 1; j <= len2; j++) { | ||||||
|  |                 const cost = str1[i - 1] === str2[j - 1] ? 0 : 1; | ||||||
|  |                 currentRow[j] = Math.min( | ||||||
|  |                     previousRow[j] + 1,        // deletion | ||||||
|  |                     currentRow[j - 1] + 1,      // insertion | ||||||
|  |                     previousRow[j - 1] + cost  // substitution | ||||||
|  |                 ); | ||||||
|  |                  | ||||||
|  |                 if (currentRow[j] < minInRow) { | ||||||
|  |                     minInRow = currentRow[j]; | ||||||
|  |                 } | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Early termination: minimum distance in row exceeds threshold | ||||||
|  |             if (minInRow > maxDistance) { | ||||||
|  |                 return maxDistance + 1; | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             // Swap arrays for next iteration | ||||||
|  |             [previousRow, currentRow] = [currentRow, previousRow]; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         const result = previousRow[len2]; | ||||||
|  |         return result <= maxDistance ? result : maxDistance + 1; | ||||||
|  |     } | ||||||
|  |  | ||||||
|  |     /** | ||||||
|  |      * Test if a string matches a JavaScript regular expression | ||||||
|  |      *  | ||||||
|  |      * SQLite will pass 2 or 3 arguments: | ||||||
|  |      * - 2 args: text, pattern (uses default flags 'i') | ||||||
|  |      * - 3 args: text, pattern, flags | ||||||
|  |      *  | ||||||
|  |      * @returns 1 if match, 0 if no match, null on error | ||||||
|  |      */ | ||||||
|  |     private regexMatch(...args: any[]): number | null { | ||||||
|  |         // Handle variable arguments from SQLite | ||||||
|  |         let text: string | null | undefined = args[0]; | ||||||
|  |         let pattern: string | null | undefined = args[1]; | ||||||
|  |         let flags: string = args.length > 2 ? args[2] : 'i'; | ||||||
|  |         if (!text || !pattern) { | ||||||
|  |             return 0; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         if (typeof text !== 'string' || typeof pattern !== 'string') { | ||||||
|  |             return null; | ||||||
|  |         } | ||||||
|  |  | ||||||
|  |         try { | ||||||
|  |             // Validate flags | ||||||
|  |             const validFlags = ['i', 'g', 'm', 's', 'u', 'y']; | ||||||
|  |             const flagsArray = (flags || '').split(''); | ||||||
|  |             if (!flagsArray.every(f => validFlags.includes(f))) { | ||||||
|  |                 flags = 'i'; // Fall back to case-insensitive | ||||||
|  |             } | ||||||
|  |  | ||||||
|  |             const regex = new RegExp(pattern, flags); | ||||||
|  |             return regex.test(text) ? 1 : 0; | ||||||
|  |         } catch (error) { | ||||||
|  |             // Invalid regex pattern | ||||||
|  |             log.error(`Invalid regex pattern in SQL: ${pattern} - ${error}`); | ||||||
|  |             return null; | ||||||
|  |         } | ||||||
|  |     } | ||||||
|  | } | ||||||
|  |  | ||||||
|  | // Export singleton instance getter | ||||||
|  | export function getSqliteFunctionsService(): SqliteFunctionsService { | ||||||
|  |     return SqliteFunctionsService.getInstance(); | ||||||
|  | } | ||||||
|  |  | ||||||
|  | /** | ||||||
|  |  * Initialize SQLite custom functions with the given database connection | ||||||
|  |  * This should be called once during application startup after the database is opened | ||||||
|  |  *  | ||||||
|  |  * @param db The better-sqlite3 database connection | ||||||
|  |  * @returns true if successful, false otherwise | ||||||
|  |  */ | ||||||
|  | export function initializeSqliteFunctions(db: Database): boolean { | ||||||
|  |     const service = getSqliteFunctionsService(); | ||||||
|  |     return service.registerFunctions(db); | ||||||
|  | } | ||||||
| @@ -14,6 +14,7 @@ import ws from "./ws.js"; | |||||||
| import becca_loader from "../becca/becca_loader.js"; | import becca_loader from "../becca/becca_loader.js"; | ||||||
| import entity_changes from "./entity_changes.js"; | import entity_changes from "./entity_changes.js"; | ||||||
| import config from "./config.js"; | import config from "./config.js"; | ||||||
|  | import { initializeSqliteFunctions } from "./search/sqlite_functions.js"; | ||||||
|  |  | ||||||
| const dbOpts: Database.Options = { | const dbOpts: Database.Options = { | ||||||
|     nativeBinding: process.env.BETTERSQLITE3_NATIVE_PATH || undefined |     nativeBinding: process.env.BETTERSQLITE3_NATIVE_PATH || undefined | ||||||
| @@ -49,12 +50,33 @@ function rebuildIntegrationTestDatabase(dbPath?: string) { | |||||||
|     // This allows a database that is read normally but is kept in memory and discards all modifications. |     // This allows a database that is read normally but is kept in memory and discards all modifications. | ||||||
|     dbConnection = buildIntegrationTestDatabase(dbPath); |     dbConnection = buildIntegrationTestDatabase(dbPath); | ||||||
|     statementCache = {}; |     statementCache = {}; | ||||||
|  |      | ||||||
|  |     // Re-register custom SQLite functions after rebuilding the database | ||||||
|  |     try { | ||||||
|  |         initializeSqliteFunctions(dbConnection); | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`Failed to re-initialize SQLite custom functions after rebuild: ${error}`); | ||||||
|  |     } | ||||||
| } | } | ||||||
|  |  | ||||||
| if (!process.env.TRILIUM_INTEGRATION_TEST) { | if (!process.env.TRILIUM_INTEGRATION_TEST) { | ||||||
|     dbConnection.pragma("journal_mode = WAL"); |     dbConnection.pragma("journal_mode = WAL"); | ||||||
| } | } | ||||||
|  |  | ||||||
|  | // Initialize custom SQLite functions for search operations | ||||||
|  | // This must happen after the database connection is established | ||||||
|  | try { | ||||||
|  |     const functionsRegistered = initializeSqliteFunctions(dbConnection); | ||||||
|  |     if (functionsRegistered) { | ||||||
|  |         log.info("SQLite custom search functions initialized successfully"); | ||||||
|  |     } else { | ||||||
|  |         log.info("SQLite custom search functions initialization failed - search will use fallback methods"); | ||||||
|  |     } | ||||||
|  | } catch (error) { | ||||||
|  |     log.error(`Failed to initialize SQLite custom functions: ${error}`); | ||||||
|  |     // Continue without custom functions - triggers will use LOWER() as fallback | ||||||
|  | } | ||||||
|  |  | ||||||
| const LOG_ALL_QUERIES = false; | const LOG_ALL_QUERIES = false; | ||||||
|  |  | ||||||
| type Params = any; | type Params = any; | ||||||
| @@ -367,6 +389,10 @@ function disableSlowQueryLogging<T>(cb: () => T) { | |||||||
|     } |     } | ||||||
| } | } | ||||||
|  |  | ||||||
|  | function getDbConnection(): DatabaseType { | ||||||
|  |     return dbConnection; | ||||||
|  | } | ||||||
|  |  | ||||||
| export default { | export default { | ||||||
|     insert, |     insert, | ||||||
|     replace, |     replace, | ||||||
| @@ -434,5 +460,6 @@ export default { | |||||||
|     fillParamList, |     fillParamList, | ||||||
|     copyDatabase, |     copyDatabase, | ||||||
|     disableSlowQueryLogging, |     disableSlowQueryLogging, | ||||||
|     rebuildIntegrationTestDatabase |     rebuildIntegrationTestDatabase, | ||||||
|  |     getDbConnection | ||||||
| }; | }; | ||||||
|   | |||||||
| @@ -67,6 +67,21 @@ async function initDbConnection() { | |||||||
|         PRIMARY KEY (tmpID) |         PRIMARY KEY (tmpID) | ||||||
|     );`) |     );`) | ||||||
|  |  | ||||||
|  |     // Register SQLite search functions after database is ready | ||||||
|  |     try { | ||||||
|  |         const { getSqliteFunctionsService } = await import("./search/sqlite_functions.js"); | ||||||
|  |         const functionsService = getSqliteFunctionsService(); | ||||||
|  |         const db = sql.getDbConnection(); | ||||||
|  |          | ||||||
|  |         if (functionsService.registerFunctions(db)) { | ||||||
|  |             log.info("SQLite search functions registered successfully"); | ||||||
|  |         } else { | ||||||
|  |             log.info("SQLite search functions registration skipped (already registered)"); | ||||||
|  |         } | ||||||
|  |     } catch (error) { | ||||||
|  |         log.error(`Failed to register SQLite search functions: ${error}`); | ||||||
|  |     } | ||||||
|  |  | ||||||
|     dbReady.resolve(); |     dbReady.resolve(); | ||||||
| } | } | ||||||
|  |  | ||||||
|   | |||||||
		Reference in New Issue
	
	Block a user