@@ -219,14 +219,23 @@ CREATE TABLE IF NOT EXISTS sessions (
219219);
220220
221221-- FTS5 Full-Text Search Support
222- -- Create FTS5 virtual table for full-text searching
222+ -- Create FTS5 virtual table with porter stemming for word-based searches
223223CREATE VIRTUAL TABLE notes_fts USING fts5(
224224 noteId UNINDEXED,
225225 title,
226226 content,
227227 tokenize = ' porter unicode61'
228228);
229229
230+ -- Create FTS5 virtual table with trigram tokenizer for substring searches
231+ CREATE VIRTUAL TABLE notes_fts_trigram USING fts5(
232+ noteId UNINDEXED,
233+ title,
234+ content,
235+ tokenize = ' trigram' ,
236+ detail = ' none'
237+ );
238+
230239-- Triggers to keep FTS table synchronized with notes
231240-- IMPORTANT: These triggers must handle all SQL operations including:
232241-- - Regular INSERT/UPDATE/DELETE
@@ -242,17 +251,26 @@ WHEN NEW.type IN ('text', 'code', 'mermaid', 'canvas', 'mindMap')
242251 AND NEW .isDeleted = 0
243252 AND NEW .isProtected = 0
244253BEGIN
245- -- First delete any existing FTS entry (in case of INSERT OR REPLACE)
254+ -- First delete any existing FTS entries (in case of INSERT OR REPLACE)
246255 DELETE FROM notes_fts WHERE noteId = NEW .noteId ;
256+ DELETE FROM notes_fts_trigram WHERE noteId = NEW .noteId ;
247257
248- -- Then insert the new entry, using LEFT JOIN to handle missing blobs
258+ -- Then insert the new entry into both FTS tables
249259 INSERT INTO notes_fts (noteId, title, content)
250260 SELECT
251261 NEW .noteId ,
252262 NEW .title ,
253263 COALESCE(b .content , ' ' ) -- Use empty string if blob doesn't exist yet
254264 FROM (SELECT NEW .noteId ) AS note_select
255265 LEFT JOIN blobs b ON b .blobId = NEW .blobId ;
266+
267+ INSERT INTO notes_fts_trigram (noteId, title, content)
268+ SELECT
269+ NEW .noteId ,
270+ NEW .title ,
271+ COALESCE(b .content , ' ' )
272+ FROM (SELECT NEW .noteId ) AS note_select
273+ LEFT JOIN blobs b ON b .blobId = NEW .blobId ;
256274END;
257275
258276-- Trigger for UPDATE operations on notes table
@@ -263,10 +281,11 @@ AFTER UPDATE ON notes
263281WHEN NEW .type IN (' text' , ' code' , ' mermaid' , ' canvas' , ' mindMap' )
264282 -- Fire on any change, not just specific columns, to handle all upsert scenarios
265283BEGIN
266- -- Always delete the old entry
284+ -- Always delete the old entries from both FTS tables
267285 DELETE FROM notes_fts WHERE noteId = NEW .noteId ;
286+ DELETE FROM notes_fts_trigram WHERE noteId = NEW .noteId ;
268287
269- -- Insert new entry if note is not deleted and not protected
288+ -- Insert new entries into both FTS tables if note is not deleted and not protected
270289 INSERT INTO notes_fts (noteId, title, content)
271290 SELECT
272291 NEW .noteId ,
@@ -276,6 +295,16 @@ BEGIN
276295 LEFT JOIN blobs b ON b .blobId = NEW .blobId
277296 WHERE NEW .isDeleted = 0
278297 AND NEW .isProtected = 0 ;
298+
299+ INSERT INTO notes_fts_trigram (noteId, title, content)
300+ SELECT
301+ NEW .noteId ,
302+ NEW .title ,
303+ COALESCE(b .content , ' ' )
304+ FROM (SELECT NEW .noteId ) AS note_select
305+ LEFT JOIN blobs b ON b .blobId = NEW .blobId
306+ WHERE NEW .isDeleted = 0
307+ AND NEW .isProtected = 0 ;
279308END;
280309
281310-- Trigger for UPDATE operations on blobs
284313CREATE TRIGGER notes_fts_blob_update
285314AFTER UPDATE ON blobs
286315BEGIN
287- -- Use INSERT OR REPLACE for atomic update of all notes sharing this blob
288- -- This is more efficient than DELETE + INSERT when many notes share the same blob
316+ -- Update both FTS tables for all notes sharing this blob
289317 INSERT OR REPLACE INTO notes_fts (noteId, title, content)
290318 SELECT
291319 n .noteId ,
@@ -296,13 +324,25 @@ BEGIN
296324 AND n .type IN (' text' , ' code' , ' mermaid' , ' canvas' , ' mindMap' )
297325 AND n .isDeleted = 0
298326 AND n .isProtected = 0 ;
327+
328+ INSERT OR REPLACE INTO notes_fts_trigram (noteId, title, content)
329+ SELECT
330+ n .noteId ,
331+ n .title ,
332+ NEW .content
333+ FROM notes n
334+ WHERE n .blobId = NEW .blobId
335+ AND n .type IN (' text' , ' code' , ' mermaid' , ' canvas' , ' mindMap' )
336+ AND n .isDeleted = 0
337+ AND n .isProtected = 0 ;
299338END;
300339
301340-- Trigger for DELETE operations
302341CREATE TRIGGER notes_fts_delete
303342AFTER DELETE ON notes
304343BEGIN
305344 DELETE FROM notes_fts WHERE noteId = OLD .noteId ;
345+ DELETE FROM notes_fts_trigram WHERE noteId = OLD .noteId ;
306346END;
307347
308348-- Trigger for soft delete (isDeleted = 1)
@@ -311,6 +351,7 @@ AFTER UPDATE ON notes
311351WHEN OLD .isDeleted = 0 AND NEW .isDeleted = 1
312352BEGIN
313353 DELETE FROM notes_fts WHERE noteId = NEW .noteId ;
354+ DELETE FROM notes_fts_trigram WHERE noteId = NEW .noteId ;
314355END;
315356
316357-- Trigger for notes becoming protected
@@ -320,6 +361,7 @@ AFTER UPDATE ON notes
320361WHEN OLD .isProtected = 0 AND NEW .isProtected = 1
321362BEGIN
322363 DELETE FROM notes_fts WHERE noteId = NEW .noteId ;
364+ DELETE FROM notes_fts_trigram WHERE noteId = NEW .noteId ;
323365END;
324366
325367-- Trigger for notes becoming unprotected
@@ -331,6 +373,7 @@ WHEN OLD.isProtected = 1 AND NEW.isProtected = 0
331373 AND NEW .isDeleted = 0
332374BEGIN
333375 DELETE FROM notes_fts WHERE noteId = NEW .noteId ;
376+ DELETE FROM notes_fts_trigram WHERE noteId = NEW .noteId ;
334377
335378 INSERT INTO notes_fts (noteId, title, content)
336379 SELECT
@@ -339,6 +382,14 @@ BEGIN
339382 COALESCE(b .content , ' ' )
340383 FROM (SELECT NEW .noteId ) AS note_select
341384 LEFT JOIN blobs b ON b .blobId = NEW .blobId ;
385+
386+ INSERT INTO notes_fts_trigram (noteId, title, content)
387+ SELECT
388+ NEW .noteId ,
389+ NEW .title ,
390+ COALESCE(b .content , ' ' )
391+ FROM (SELECT NEW .noteId ) AS note_select
392+ LEFT JOIN blobs b ON b .blobId = NEW .blobId ;
342393END;
343394
344395-- Trigger for INSERT operations on blobs
347398CREATE TRIGGER notes_fts_blob_insert
348399AFTER INSERT ON blobs
349400BEGIN
350- -- Use INSERT OR REPLACE to handle both new and existing FTS entries
351- -- This is crucial for blob deduplication where multiple notes may already
352- -- exist that reference this blob before the blob itself is created
401+ -- Update both FTS tables for all notes that reference this blob
353402 INSERT OR REPLACE INTO notes_fts (noteId, title, content)
354403 SELECT
355404 n .noteId ,
@@ -360,4 +409,15 @@ BEGIN
360409 AND n .type IN (' text' , ' code' , ' mermaid' , ' canvas' , ' mindMap' )
361410 AND n .isDeleted = 0
362411 AND n .isProtected = 0 ;
412+
413+ INSERT OR REPLACE INTO notes_fts_trigram (noteId, title, content)
414+ SELECT
415+ n .noteId ,
416+ n .title ,
417+ NEW .content
418+ FROM notes n
419+ WHERE n .blobId = NEW .blobId
420+ AND n .type IN (' text' , ' code' , ' mermaid' , ' canvas' , ' mindMap' )
421+ AND n .isDeleted = 0
422+ AND n .isProtected = 0 ;
363423END;
0 commit comments