Skip to main content
This requires creating a separate FTS5 table(s) to index the data, and updating the table(s) using SQLite triggers. Full-text search has been demonstrated in the following SDKs: Note that the availability of FTS in our SDKs is dependent on the underlying sqlite package used. It may be supported in our other SDKs, especially if the FTS5 extension is available, but would be untested. Check with us on Discord if you have a use case and need help getting started.

Example Implementations

FTS is implemented in the following demo apps: We explain the Flutter/Dart implementation in more detail below. Example code is shown mainly in Dart, but references to the React, React Native and Swift equivalents are included where relevant, so you should be able to cross-reference.

Walkthrough (Dart): Full-text search in the To-Do List Demo App

Setup

First, we need to set up the FTS tables to match the lists and todos tables already created in this demo app. Don’t worry if you already have data in the tables, as it will be copied into the new FTS tables. FTS tables are created when instantiating the client-side PowerSync database.
    // https://github.com/powersync-ja/powersync.dart/blob/master/demos/supabase-todolist/lib/powersync.dart#L186
    
    Future<void> openDatabase() async {
      ...
      await configureFts(db);
    }
To simplify implementation these examples make use of SQLite migrations. The migrations are run in migrations/fts_setup.dart in the Flutter implementation. Here we use the sqlite_async Dart package to generate the migrations.
// migrations/fts_setup.dart

/// This is where you can add more migrations to generate FTS tables
/// that correspond to the tables in your schema and populate them
/// with the data you would like to search on
Future<void> configureFts(PowerSyncDatabase db) async {
  migrations
    ..add(createFtsMigration(
        migrationVersion: 1,
        tableName: 'lists',
        columns: ['name'],
        tokenizationMethod: 'porter unicode61'))
    ..add(createFtsMigration(
      migrationVersion: 2,
      tableName: 'todos',
      columns: ['description', 'list_id'],
    ));
  await migrations.migrate(db);
}
The createFtsMigration function is key and corresponds to the below (Dart example):
// migrations/fts_setup.dart

/// Create a Full Text Search table for the given table and columns
/// with an option to use a different tokenizer otherwise it defaults
/// to unicode61. It also creates the triggers that keep the FTS table
/// and the PowerSync table in sync.
SqliteMigration createFtsMigration(
    {required int migrationVersion,
    required String tableName,
    required List<String> columns,
    String tokenizationMethod = 'unicode61'}) {
  String internalName =
      schema.tables.firstWhere((table) => table.name == tableName).internalName;
  String stringColumns = columns.join(', ');

  return SqliteMigration(migrationVersion, (tx) async {
    // Add FTS table
    await tx.execute('''
      CREATE VIRTUAL TABLE IF NOT EXISTS fts_$tableName
      USING fts5(id UNINDEXED, $stringColumns, tokenize='$tokenizationMethod');
    ''');
    // Copy over records already in table
    await tx.execute('''
      INSERT INTO fts_$tableName(rowid, id, $stringColumns)
      SELECT rowid, id, ${generateJsonExtracts(ExtractType.columnOnly, 'data', columns)}
      FROM $internalName;
    ''');
    // Add INSERT, UPDATE and DELETE and triggers to keep fts table in sync with table
    await tx.execute('''
      CREATE TRIGGER IF NOT EXISTS fts_insert_trigger_$tableName AFTER INSERT
      ON $internalName
      BEGIN
        INSERT INTO fts_$tableName(rowid, id, $stringColumns)
        VALUES (
          NEW.rowid,
          NEW.id,
          ${generateJsonExtracts(ExtractType.columnOnly, 'NEW.data', columns)}
        );
      END;
    ''');
    await tx.execute('''
      CREATE TRIGGER IF NOT EXISTS fts_update_trigger_$tableName AFTER UPDATE
      ON $internalName BEGIN
        UPDATE fts_$tableName
        SET ${generateJsonExtracts(ExtractType.columnInOperation, 'NEW.data', columns)}
        WHERE rowid = NEW.rowid;
      END;
    ''');
    await tx.execute('''
      CREATE TRIGGER IF NOT EXISTS fts_delete_trigger_$tableName AFTER DELETE
      ON $internalName BEGIN
        DELETE FROM fts_$tableName WHERE rowid = OLD.rowid;
      END;
    ''');
  });
}
After this is run, you should have the following tables and triggers in your SQLite DB: