From 3dfd5c7c2b62a4dff6f9897e4e5dc6ed6d5baa2d Mon Sep 17 00:00:00 2001 From: fullex <0xfullex@gmail.com> Date: Sun, 4 Jan 2026 01:07:04 +0800 Subject: [PATCH] feat: add custom SQL handling for triggers and virtual tables - Introduced a new method `runCustomMigrations` in `DbService` to execute custom SQL statements that Drizzle cannot manage, such as triggers and virtual tables. - Updated `database-patterns.md` and `README.md` to document the handling of custom SQL and its importance in maintaining database integrity during migrations. - Refactored `messageFts.ts` to define FTS5 virtual table and associated triggers as idempotent SQL statements for better migration management. --- docs/en/references/data/database-patterns.md | 8 + .../sqlite-drizzle/meta/0001_snapshot.json | 968 +++++++++--------- migrations/sqlite-drizzle/meta/_journal.json | 8 +- src/main/data/db/DbService.ts | 25 + src/main/data/db/README.md | 6 + src/main/data/db/customSql.ts | 25 + src/main/data/db/schemas/messageFts.ts | 88 +- 7 files changed, 567 insertions(+), 561 deletions(-) create mode 100644 src/main/data/db/customSql.ts diff --git a/docs/en/references/data/database-patterns.md b/docs/en/references/data/database-patterns.md index 10d3a44593..c4745832b9 100644 --- a/docs/en/references/data/database-patterns.md +++ b/docs/en/references/data/database-patterns.md @@ -197,3 +197,11 @@ return this.getById(id) The schema supports soft delete via `deletedAt` field (see `createUpdateDeleteTimestamps`). Business logic can choose to use soft delete or hard delete based on requirements. + +## Custom SQL + +Drizzle cannot manage triggers and virtual tables (e.g., FTS5). These are defined in `customSql.ts` and run automatically after every migration. + +**Why**: SQLite's `DROP TABLE` removes associated triggers. When Drizzle modifies a table schema, it drops and recreates the table, losing triggers in the process. + +**Adding new custom SQL**: Define statements as `string[]` in the relevant schema file, then spread into `CUSTOM_SQL_STATEMENTS` in `customSql.ts`. All statements must use `IF NOT EXISTS` to be idempotent. diff --git a/migrations/sqlite-drizzle/meta/0001_snapshot.json b/migrations/sqlite-drizzle/meta/0001_snapshot.json index 6c263b18df..7560d37a6c 100644 --- a/migrations/sqlite-drizzle/meta/0001_snapshot.json +++ b/migrations/sqlite-drizzle/meta/0001_snapshot.json @@ -1,370 +1,188 @@ { - "version": "6", + "_meta": { + "columns": {}, + "schemas": {}, + "tables": {} + }, "dialect": "sqlite", + "enums": {}, "id": "a433b120-0ab8-4f3f-9d1d-766b48c216c8", + "internal": { + "indexes": {} + }, "prevId": "2ee6f7b2-99da-4de1-b895-48866855b7c6", "tables": { "app_state": { - "name": "app_state", + "checkConstraints": {}, "columns": { - "key": { - "name": "key", - "type": "text", - "primaryKey": true, - "notNull": true, - "autoincrement": false - }, - "value": { - "name": "value", - "type": "text", + "created_at": { + "autoincrement": false, + "name": "created_at", + "notNull": false, "primaryKey": false, - "notNull": true, - "autoincrement": false + "type": "integer" }, "description": { + "autoincrement": false, "name": "description", - "type": "text", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "text" }, - "created_at": { - "name": "created_at", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false + "key": { + "autoincrement": false, + "name": "key", + "notNull": true, + "primaryKey": true, + "type": "text" }, "updated_at": { + "autoincrement": false, "name": "updated_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" + }, + "value": { + "autoincrement": false, + "name": "value", + "notNull": true, + "primaryKey": false, + "type": "text" } }, - "indexes": {}, - "foreignKeys": {}, "compositePrimaryKeys": {}, - "uniqueConstraints": {}, - "checkConstraints": {} + "foreignKeys": {}, + "indexes": {}, + "name": "app_state", + "uniqueConstraints": {} }, "entity_tag": { - "name": "entity_tag", + "checkConstraints": {}, "columns": { - "entity_type": { - "name": "entity_type", - "type": "text", + "created_at": { + "autoincrement": false, + "name": "created_at", + "notNull": false, "primaryKey": false, - "notNull": true, - "autoincrement": false + "type": "integer" }, "entity_id": { + "autoincrement": false, "name": "entity_id", - "type": "text", - "primaryKey": false, "notNull": true, - "autoincrement": false + "primaryKey": false, + "type": "text" + }, + "entity_type": { + "autoincrement": false, + "name": "entity_type", + "notNull": true, + "primaryKey": false, + "type": "text" }, "tag_id": { + "autoincrement": false, "name": "tag_id", - "type": "text", - "primaryKey": false, "notNull": true, - "autoincrement": false - }, - "created_at": { - "name": "created_at", - "type": "integer", "primaryKey": false, - "notNull": false, - "autoincrement": false + "type": "text" }, "updated_at": { + "autoincrement": false, "name": "updated_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false - } - }, - "indexes": { - "entity_tag_tag_id_idx": { - "name": "entity_tag_tag_id_idx", - "columns": [ - "tag_id" - ], - "isUnique": false - } - }, - "foreignKeys": { - "entity_tag_tag_id_tag_id_fk": { - "name": "entity_tag_tag_id_tag_id_fk", - "tableFrom": "entity_tag", - "tableTo": "tag", - "columnsFrom": [ - "tag_id" - ], - "columnsTo": [ - "id" - ], - "onDelete": "cascade", - "onUpdate": "no action" + "primaryKey": false, + "type": "integer" } }, "compositePrimaryKeys": { "entity_tag_entity_type_entity_id_tag_id_pk": { - "columns": [ - "entity_type", - "entity_id", - "tag_id" - ], + "columns": ["entity_type", "entity_id", "tag_id"], "name": "entity_tag_entity_type_entity_id_tag_id_pk" } }, - "uniqueConstraints": {}, - "checkConstraints": {} + "foreignKeys": { + "entity_tag_tag_id_tag_id_fk": { + "columnsFrom": ["tag_id"], + "columnsTo": ["id"], + "name": "entity_tag_tag_id_tag_id_fk", + "onDelete": "cascade", + "onUpdate": "no action", + "tableFrom": "entity_tag", + "tableTo": "tag" + } + }, + "indexes": { + "entity_tag_tag_id_idx": { + "columns": ["tag_id"], + "isUnique": false, + "name": "entity_tag_tag_id_idx" + } + }, + "name": "entity_tag", + "uniqueConstraints": {} }, "group": { - "name": "group", + "checkConstraints": {}, "columns": { - "id": { - "name": "id", - "type": "text", - "primaryKey": true, - "notNull": true, - "autoincrement": false + "created_at": { + "autoincrement": false, + "name": "created_at", + "notNull": false, + "primaryKey": false, + "type": "integer" }, "entity_type": { + "autoincrement": false, "name": "entity_type", - "type": "text", - "primaryKey": false, "notNull": true, - "autoincrement": false + "primaryKey": false, + "type": "text" + }, + "id": { + "autoincrement": false, + "name": "id", + "notNull": true, + "primaryKey": true, + "type": "text" }, "name": { + "autoincrement": false, "name": "name", - "type": "text", - "primaryKey": false, "notNull": true, - "autoincrement": false + "primaryKey": false, + "type": "text" }, "sort_order": { - "name": "sort_order", - "type": "integer", - "primaryKey": false, - "notNull": false, "autoincrement": false, - "default": 0 - }, - "created_at": { - "name": "created_at", - "type": "integer", - "primaryKey": false, + "default": 0, + "name": "sort_order", "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" }, "updated_at": { + "autoincrement": false, "name": "updated_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" } }, + "compositePrimaryKeys": {}, + "foreignKeys": {}, "indexes": { "group_entity_sort_idx": { - "name": "group_entity_sort_idx", - "columns": [ - "entity_type", - "sort_order" - ], - "isUnique": false + "columns": ["entity_type", "sort_order"], + "isUnique": false, + "name": "group_entity_sort_idx" } }, - "foreignKeys": {}, - "compositePrimaryKeys": {}, - "uniqueConstraints": {}, - "checkConstraints": {} + "name": "group", + "uniqueConstraints": {} }, "message": { - "name": "message", - "columns": { - "id": { - "name": "id", - "type": "text", - "primaryKey": true, - "notNull": true, - "autoincrement": false - }, - "parent_id": { - "name": "parent_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "topic_id": { - "name": "topic_id", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, - "role": { - "name": "role", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, - "data": { - "name": "data", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, - "searchable_text": { - "name": "searchable_text", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "status": { - "name": "status", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, - "siblings_group_id": { - "name": "siblings_group_id", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false, - "default": 0 - }, - "assistant_id": { - "name": "assistant_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "assistant_meta": { - "name": "assistant_meta", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "model_id": { - "name": "model_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "model_meta": { - "name": "model_meta", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "trace_id": { - "name": "trace_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "stats": { - "name": "stats", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "created_at": { - "name": "created_at", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "updated_at": { - "name": "updated_at", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "deleted_at": { - "name": "deleted_at", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false - } - }, - "indexes": { - "message_parent_id_idx": { - "name": "message_parent_id_idx", - "columns": [ - "parent_id" - ], - "isUnique": false - }, - "message_topic_created_idx": { - "name": "message_topic_created_idx", - "columns": [ - "topic_id", - "created_at" - ], - "isUnique": false - }, - "message_trace_id_idx": { - "name": "message_trace_id_idx", - "columns": [ - "trace_id" - ], - "isUnique": false - } - }, - "foreignKeys": { - "message_topic_id_topic_id_fk": { - "name": "message_topic_id_topic_id_fk", - "tableFrom": "message", - "tableTo": "topic", - "columnsFrom": [ - "topic_id" - ], - "columnsTo": [ - "id" - ], - "onDelete": "cascade", - "onUpdate": "no action" - }, - "message_parent_id_message_id_fk": { - "name": "message_parent_id_message_id_fk", - "tableFrom": "message", - "tableTo": "message", - "columnsFrom": [ - "parent_id" - ], - "columnsTo": [ - "id" - ], - "onDelete": "set null", - "onUpdate": "no action" - } - }, - "compositePrimaryKeys": {}, - "uniqueConstraints": {}, "checkConstraints": { "message_role_check": { "name": "message_role_check", @@ -374,289 +192,421 @@ "name": "message_status_check", "value": "\"message\".\"status\" IN ('pending', 'success', 'error', 'paused')" } - } - }, - "preference": { - "name": "preference", + }, "columns": { - "scope": { - "name": "scope", - "type": "text", - "primaryKey": false, - "notNull": true, + "assistant_id": { "autoincrement": false, - "default": "'default'" - }, - "key": { - "name": "key", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, - "value": { - "name": "value", - "type": "text", - "primaryKey": false, + "name": "assistant_id", "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "text" + }, + "assistant_meta": { + "autoincrement": false, + "name": "assistant_meta", + "notNull": false, + "primaryKey": false, + "type": "text" }, "created_at": { + "autoincrement": false, "name": "created_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" + }, + "data": { + "autoincrement": false, + "name": "data", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "deleted_at": { + "autoincrement": false, + "name": "deleted_at", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "id": { + "autoincrement": false, + "name": "id", + "notNull": true, + "primaryKey": true, + "type": "text" + }, + "model_id": { + "autoincrement": false, + "name": "model_id", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "model_meta": { + "autoincrement": false, + "name": "model_meta", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "parent_id": { + "autoincrement": false, + "name": "parent_id", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "role": { + "autoincrement": false, + "name": "role", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "searchable_text": { + "autoincrement": false, + "name": "searchable_text", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "siblings_group_id": { + "autoincrement": false, + "default": 0, + "name": "siblings_group_id", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "stats": { + "autoincrement": false, + "name": "stats", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "status": { + "autoincrement": false, + "name": "status", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "topic_id": { + "autoincrement": false, + "name": "topic_id", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "trace_id": { + "autoincrement": false, + "name": "trace_id", + "notNull": false, + "primaryKey": false, + "type": "text" }, "updated_at": { + "autoincrement": false, "name": "updated_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" + } + }, + "compositePrimaryKeys": {}, + "foreignKeys": { + "message_parent_id_message_id_fk": { + "columnsFrom": ["parent_id"], + "columnsTo": ["id"], + "name": "message_parent_id_message_id_fk", + "onDelete": "set null", + "onUpdate": "no action", + "tableFrom": "message", + "tableTo": "message" + }, + "message_topic_id_topic_id_fk": { + "columnsFrom": ["topic_id"], + "columnsTo": ["id"], + "name": "message_topic_id_topic_id_fk", + "onDelete": "cascade", + "onUpdate": "no action", + "tableFrom": "message", + "tableTo": "topic" + } + }, + "indexes": { + "message_parent_id_idx": { + "columns": ["parent_id"], + "isUnique": false, + "name": "message_parent_id_idx" + }, + "message_topic_created_idx": { + "columns": ["topic_id", "created_at"], + "isUnique": false, + "name": "message_topic_created_idx" + }, + "message_trace_id_idx": { + "columns": ["trace_id"], + "isUnique": false, + "name": "message_trace_id_idx" + } + }, + "name": "message", + "uniqueConstraints": {} + }, + "preference": { + "checkConstraints": {}, + "columns": { + "created_at": { + "autoincrement": false, + "name": "created_at", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "key": { + "autoincrement": false, + "name": "key", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "scope": { + "autoincrement": false, + "default": "'default'", + "name": "scope", + "notNull": true, + "primaryKey": false, + "type": "text" + }, + "updated_at": { + "autoincrement": false, + "name": "updated_at", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "value": { + "autoincrement": false, + "name": "value", + "notNull": false, + "primaryKey": false, + "type": "text" } }, - "indexes": {}, - "foreignKeys": {}, "compositePrimaryKeys": { "preference_scope_key_pk": { - "columns": [ - "scope", - "key" - ], + "columns": ["scope", "key"], "name": "preference_scope_key_pk" } }, - "uniqueConstraints": {}, - "checkConstraints": {} + "foreignKeys": {}, + "indexes": {}, + "name": "preference", + "uniqueConstraints": {} }, "tag": { - "name": "tag", + "checkConstraints": {}, "columns": { - "id": { - "name": "id", - "type": "text", - "primaryKey": true, - "notNull": true, - "autoincrement": false - }, - "name": { - "name": "name", - "type": "text", - "primaryKey": false, - "notNull": true, - "autoincrement": false - }, "color": { + "autoincrement": false, "name": "color", - "type": "text", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "text" }, "created_at": { + "autoincrement": false, "name": "created_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" + }, + "id": { + "autoincrement": false, + "name": "id", + "notNull": true, + "primaryKey": true, + "type": "text" + }, + "name": { + "autoincrement": false, + "name": "name", + "notNull": true, + "primaryKey": false, + "type": "text" }, "updated_at": { + "autoincrement": false, "name": "updated_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" } }, + "compositePrimaryKeys": {}, + "foreignKeys": {}, "indexes": { "tag_name_unique": { - "name": "tag_name_unique", - "columns": [ - "name" - ], - "isUnique": true + "columns": ["name"], + "isUnique": true, + "name": "tag_name_unique" } }, - "foreignKeys": {}, - "compositePrimaryKeys": {}, - "uniqueConstraints": {}, - "checkConstraints": {} + "name": "tag", + "uniqueConstraints": {} }, "topic": { - "name": "topic", + "checkConstraints": {}, "columns": { - "id": { - "name": "id", - "type": "text", - "primaryKey": true, - "notNull": true, - "autoincrement": false - }, - "name": { - "name": "name", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "is_name_manually_edited": { - "name": "is_name_manually_edited", - "type": "integer", - "primaryKey": false, - "notNull": false, + "active_node_id": { "autoincrement": false, - "default": false + "name": "active_node_id", + "notNull": false, + "primaryKey": false, + "type": "text" }, "assistant_id": { + "autoincrement": false, "name": "assistant_id", - "type": "text", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "text" }, "assistant_meta": { + "autoincrement": false, "name": "assistant_meta", - "type": "text", - "primaryKey": false, "notNull": false, - "autoincrement": false - }, - "prompt": { - "name": "prompt", - "type": "text", "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "active_node_id": { - "name": "active_node_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "group_id": { - "name": "group_id", - "type": "text", - "primaryKey": false, - "notNull": false, - "autoincrement": false - }, - "sort_order": { - "name": "sort_order", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false, - "default": 0 - }, - "is_pinned": { - "name": "is_pinned", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false, - "default": false - }, - "pinned_order": { - "name": "pinned_order", - "type": "integer", - "primaryKey": false, - "notNull": false, - "autoincrement": false, - "default": 0 + "type": "text" }, "created_at": { + "autoincrement": false, "name": "created_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false - }, - "updated_at": { - "name": "updated_at", - "type": "integer", "primaryKey": false, - "notNull": false, - "autoincrement": false + "type": "integer" }, "deleted_at": { + "autoincrement": false, "name": "deleted_at", - "type": "integer", - "primaryKey": false, "notNull": false, - "autoincrement": false + "primaryKey": false, + "type": "integer" + }, + "group_id": { + "autoincrement": false, + "name": "group_id", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "id": { + "autoincrement": false, + "name": "id", + "notNull": true, + "primaryKey": true, + "type": "text" + }, + "is_name_manually_edited": { + "autoincrement": false, + "default": false, + "name": "is_name_manually_edited", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "is_pinned": { + "autoincrement": false, + "default": false, + "name": "is_pinned", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "name": { + "autoincrement": false, + "name": "name", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "pinned_order": { + "autoincrement": false, + "default": 0, + "name": "pinned_order", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "prompt": { + "autoincrement": false, + "name": "prompt", + "notNull": false, + "primaryKey": false, + "type": "text" + }, + "sort_order": { + "autoincrement": false, + "default": 0, + "name": "sort_order", + "notNull": false, + "primaryKey": false, + "type": "integer" + }, + "updated_at": { + "autoincrement": false, + "name": "updated_at", + "notNull": false, + "primaryKey": false, + "type": "integer" + } + }, + "compositePrimaryKeys": {}, + "foreignKeys": { + "topic_group_id_group_id_fk": { + "columnsFrom": ["group_id"], + "columnsTo": ["id"], + "name": "topic_group_id_group_id_fk", + "onDelete": "set null", + "onUpdate": "no action", + "tableFrom": "topic", + "tableTo": "group" } }, "indexes": { - "topic_group_updated_idx": { - "name": "topic_group_updated_idx", - "columns": [ - "group_id", - "updated_at" - ], - "isUnique": false + "topic_assistant_id_idx": { + "columns": ["assistant_id"], + "isUnique": false, + "name": "topic_assistant_id_idx" }, "topic_group_sort_idx": { - "name": "topic_group_sort_idx", - "columns": [ - "group_id", - "sort_order" - ], - "isUnique": false + "columns": ["group_id", "sort_order"], + "isUnique": false, + "name": "topic_group_sort_idx" }, - "topic_updated_at_idx": { - "name": "topic_updated_at_idx", - "columns": [ - "updated_at" - ], - "isUnique": false + "topic_group_updated_idx": { + "columns": ["group_id", "updated_at"], + "isUnique": false, + "name": "topic_group_updated_idx" }, "topic_is_pinned_idx": { - "name": "topic_is_pinned_idx", - "columns": [ - "is_pinned", - "pinned_order" - ], - "isUnique": false + "columns": ["is_pinned", "pinned_order"], + "isUnique": false, + "name": "topic_is_pinned_idx" }, - "topic_assistant_id_idx": { - "name": "topic_assistant_id_idx", - "columns": [ - "assistant_id" - ], - "isUnique": false + "topic_updated_at_idx": { + "columns": ["updated_at"], + "isUnique": false, + "name": "topic_updated_at_idx" } }, - "foreignKeys": { - "topic_group_id_group_id_fk": { - "name": "topic_group_id_group_id_fk", - "tableFrom": "topic", - "tableTo": "group", - "columnsFrom": [ - "group_id" - ], - "columnsTo": [ - "id" - ], - "onDelete": "set null", - "onUpdate": "no action" - } - }, - "compositePrimaryKeys": {}, - "uniqueConstraints": {}, - "checkConstraints": {} + "name": "topic", + "uniqueConstraints": {} } }, - "views": {}, - "enums": {}, - "_meta": { - "schemas": {}, - "tables": {}, - "columns": {} - }, - "internal": { - "indexes": {} - } -} \ No newline at end of file + "version": "6", + "views": {} +} diff --git a/migrations/sqlite-drizzle/meta/_journal.json b/migrations/sqlite-drizzle/meta/_journal.json index 09f883d363..c2bac3b325 100644 --- a/migrations/sqlite-drizzle/meta/_journal.json +++ b/migrations/sqlite-drizzle/meta/_journal.json @@ -9,12 +9,12 @@ "when": 1767272575118 }, { + "breakpoints": true, "idx": 1, - "version": "6", - "when": 1767455592181, "tag": "0001_futuristic_human_fly", - "breakpoints": true + "version": "6", + "when": 1767455592181 } ], "version": "7" -} \ No newline at end of file +} diff --git a/src/main/data/db/DbService.ts b/src/main/data/db/DbService.ts index 8a7edb6f33..de72be03dd 100644 --- a/src/main/data/db/DbService.ts +++ b/src/main/data/db/DbService.ts @@ -6,6 +6,7 @@ import { app } from 'electron' import path from 'path' import { pathToFileURL } from 'url' +import { CUSTOM_SQL_STATEMENTS } from './customSql' import Seeding from './seeding' import type { DbType } from './types' @@ -120,6 +121,9 @@ class DbService { const migrationsFolder = this.getMigrationsFolder() await migrate(this.db, { migrationsFolder }) + // Run custom SQL that Drizzle cannot manage (triggers, virtual tables, etc.) + await this.runCustomMigrations() + logger.info('Database migration completed successfully') } catch (error) { logger.error('Database migration failed', error as Error) @@ -127,6 +131,27 @@ class DbService { } } + /** + * Run custom SQL statements that Drizzle cannot manage + * + * This includes triggers, virtual tables, and other SQL objects. + * Called after every migration because: + * 1. Drizzle doesn't track these in schema + * 2. DROP TABLE removes associated triggers + * 3. All statements use IF NOT EXISTS, so they're idempotent + */ + private async runCustomMigrations(): Promise { + try { + for (const statement of CUSTOM_SQL_STATEMENTS) { + await this.db.run(sql.raw(statement)) + } + logger.debug('Custom migrations completed', { count: CUSTOM_SQL_STATEMENTS.length }) + } catch (error) { + logger.error('Custom migrations failed', error as Error) + throw error + } + } + /** * Get the database instance * @throws {Error} If database is not initialized diff --git a/src/main/data/db/README.md b/src/main/data/db/README.md index 0e43e760eb..2a07bd5d43 100644 --- a/src/main/data/db/README.md +++ b/src/main/data/db/README.md @@ -14,8 +14,10 @@ src/main/data/db/ │ ├── columnHelpers.ts # Reusable column definitions │ ├── topic.ts # Topic table │ ├── message.ts # Message table +│ ├── messageFts.ts # FTS5 virtual table & triggers │ └── ... # Other tables ├── seeding/ # Database initialization +├── customSql.ts # Custom SQL (triggers, virtual tables, etc.) └── DbService.ts # Database connection management ``` @@ -33,6 +35,10 @@ src/main/data/db/ yarn db:migrations:generate ``` +### Custom SQL (Triggers, Virtual Tables) + +Drizzle cannot manage triggers and virtual tables. See `customSql.ts` for how these are handled. + ### Column Helpers ```typescript diff --git a/src/main/data/db/customSql.ts b/src/main/data/db/customSql.ts new file mode 100644 index 0000000000..eaeea28db2 --- /dev/null +++ b/src/main/data/db/customSql.ts @@ -0,0 +1,25 @@ +/** + * Custom SQL statements that Drizzle cannot manage + * + * Drizzle ORM doesn't track: + * - Virtual tables (FTS5) + * - Triggers + * - Custom indexes with expressions + * + * These are executed after every migration via DbService.runCustomMigrations() + * All statements must be idempotent (use IF NOT EXISTS, etc.) + * + * To add new custom SQL: + * 1. Create statements in the relevant schema file (e.g., messageFts.ts) + * 2. Import and spread them into CUSTOM_SQL_STATEMENTS below + */ + +import { MESSAGE_FTS_STATEMENTS } from './schemas/messageFts' + +/** + * All custom SQL statements to run after migrations + */ +export const CUSTOM_SQL_STATEMENTS: string[] = [ + ...MESSAGE_FTS_STATEMENTS + // Add more custom SQL arrays here as needed +] diff --git a/src/main/data/db/schemas/messageFts.ts b/src/main/data/db/schemas/messageFts.ts index e87bcf0010..ccffbb5eaf 100644 --- a/src/main/data/db/schemas/messageFts.ts +++ b/src/main/data/db/schemas/messageFts.ts @@ -24,58 +24,50 @@ export const SEARCHABLE_TEXT_EXPRESSION = ` ` /** - * Migration SQL - Copy these statements to migration file + * Custom SQL statements that Drizzle cannot manage + * These are executed after every migration via DbService.runCustomMigrations() + * + * All statements should use IF NOT EXISTS to be idempotent. */ -export const MESSAGE_FTS_MIGRATION_SQL = ` ---> statement-breakpoint --- ============================================================ --- FTS5 Virtual Table and Triggers for Message Full-Text Search --- ============================================================ +export const MESSAGE_FTS_STATEMENTS: string[] = [ + // FTS5 virtual table, Links to message table's searchable_text column + `CREATE VIRTUAL TABLE IF NOT EXISTS message_fts USING fts5( + searchable_text, + content='message', + content_rowid='rowid', + tokenize='trigram' + )`, --- 1. Create FTS5 virtual table with external content --- Links to message table's searchable_text column -CREATE VIRTUAL TABLE IF NOT EXISTS message_fts USING fts5( - searchable_text, - content='message', - content_rowid='rowid', - tokenize='trigram' -);--> statement-breakpoint + // Trigger: populate searchable_text and sync FTS on INSERT + `CREATE TRIGGER IF NOT EXISTS message_ai AFTER INSERT ON message BEGIN + UPDATE message SET searchable_text = ( + SELECT group_concat(json_extract(value, '$.content'), ' ') + FROM json_each(json_extract(NEW.data, '$.blocks')) + WHERE json_extract(value, '$.type') = 'main_text' + ) WHERE id = NEW.id; + INSERT INTO message_fts(rowid, searchable_text) + SELECT rowid, searchable_text FROM message WHERE id = NEW.id; + END`, --- 2. Trigger: populate searchable_text and sync FTS on INSERT -CREATE TRIGGER IF NOT EXISTS message_ai AFTER INSERT ON message BEGIN - -- Extract searchable text from data.blocks - UPDATE message SET searchable_text = ( - SELECT group_concat(json_extract(value, '$.content'), ' ') - FROM json_each(json_extract(NEW.data, '$.blocks')) - WHERE json_extract(value, '$.type') = 'main_text' - ) WHERE id = NEW.id; - -- Sync to FTS5 - INSERT INTO message_fts(rowid, searchable_text) - SELECT rowid, searchable_text FROM message WHERE id = NEW.id; -END;--> statement-breakpoint + // Trigger: sync FTS on DELETE + `CREATE TRIGGER IF NOT EXISTS message_ad AFTER DELETE ON message BEGIN + INSERT INTO message_fts(message_fts, rowid, searchable_text) + VALUES ('delete', OLD.rowid, OLD.searchable_text); + END`, --- 3. Trigger: sync FTS on DELETE -CREATE TRIGGER IF NOT EXISTS message_ad AFTER DELETE ON message BEGIN - INSERT INTO message_fts(message_fts, rowid, searchable_text) - VALUES ('delete', OLD.rowid, OLD.searchable_text); -END;--> statement-breakpoint - --- 4. Trigger: update searchable_text and sync FTS on UPDATE OF data -CREATE TRIGGER IF NOT EXISTS message_au AFTER UPDATE OF data ON message BEGIN - -- Remove old FTS entry - INSERT INTO message_fts(message_fts, rowid, searchable_text) - VALUES ('delete', OLD.rowid, OLD.searchable_text); - -- Update searchable_text - UPDATE message SET searchable_text = ( - SELECT group_concat(json_extract(value, '$.content'), ' ') - FROM json_each(json_extract(NEW.data, '$.blocks')) - WHERE json_extract(value, '$.type') = 'main_text' - ) WHERE id = NEW.id; - -- Add new FTS entry - INSERT INTO message_fts(rowid, searchable_text) - SELECT rowid, searchable_text FROM message WHERE id = NEW.id; -END; -` + // Trigger: update searchable_text and sync FTS on UPDATE OF data + `CREATE TRIGGER IF NOT EXISTS message_au AFTER UPDATE OF data ON message BEGIN + INSERT INTO message_fts(message_fts, rowid, searchable_text) + VALUES ('delete', OLD.rowid, OLD.searchable_text); + UPDATE message SET searchable_text = ( + SELECT group_concat(json_extract(value, '$.content'), ' ') + FROM json_each(json_extract(NEW.data, '$.blocks')) + WHERE json_extract(value, '$.type') = 'main_text' + ) WHERE id = NEW.id; + INSERT INTO message_fts(rowid, searchable_text) + SELECT rowid, searchable_text FROM message WHERE id = NEW.id; + END` +] /** * Rebuild FTS index (run manually if needed)