diff --git a/migrations/sqlite-drizzle/0000_init.sql b/migrations/sqlite-drizzle/0000_init.sql new file mode 100644 index 0000000000..d7d9a36095 --- /dev/null +++ b/migrations/sqlite-drizzle/0000_init.sql @@ -0,0 +1,145 @@ +CREATE TABLE `app_state` ( + `key` text PRIMARY KEY NOT NULL, + `value` text NOT NULL, + `description` text, + `created_at` integer, + `updated_at` integer +); +--> statement-breakpoint +CREATE TABLE `entity_tag` ( + `entity_type` text NOT NULL, + `entity_id` text NOT NULL, + `tag_id` text NOT NULL, + `created_at` integer, + `updated_at` integer, + PRIMARY KEY(`entity_type`, `entity_id`, `tag_id`), + FOREIGN KEY (`tag_id`) REFERENCES `tag`(`id`) ON UPDATE no action ON DELETE cascade +); +--> statement-breakpoint +CREATE INDEX `entity_tag_tag_id_idx` ON `entity_tag` (`tag_id`);--> statement-breakpoint +CREATE TABLE `group` ( + `id` text PRIMARY KEY NOT NULL, + `entity_type` text NOT NULL, + `name` text NOT NULL, + `sort_order` integer DEFAULT 0, + `created_at` integer, + `updated_at` integer +); +--> statement-breakpoint +CREATE INDEX `group_entity_sort_idx` ON `group` (`entity_type`,`sort_order`);--> statement-breakpoint +CREATE TABLE `message` ( + `id` text PRIMARY KEY NOT NULL, + `topic_id` text NOT NULL, + `parent_id` text, + `response_group_id` integer DEFAULT 0, + `role` text NOT NULL, + `status` text NOT NULL, + `assistant_id` text, + `assistant_meta` text, + `model_id` text, + `model_meta` text, + `data` text NOT NULL, + `usage` text, + `metrics` text, + `trace_id` text, + `searchable_text` text, + `created_at` integer, + `updated_at` integer, + `deleted_at` integer, + FOREIGN KEY (`topic_id`) REFERENCES `topic`(`id`) ON UPDATE no action ON DELETE cascade, + FOREIGN KEY (`parent_id`) REFERENCES `message`(`id`) ON UPDATE no action ON DELETE set null, + CONSTRAINT "message_role_check" CHECK("message"."role" IN ('user', 'assistant', 'system')), + CONSTRAINT "message_status_check" CHECK("message"."status" IN ('success', 'error', 'paused')) +); +--> statement-breakpoint +CREATE INDEX `message_parent_id_idx` ON `message` (`parent_id`);--> statement-breakpoint +CREATE INDEX `message_topic_created_idx` ON `message` (`topic_id`,`created_at`);--> statement-breakpoint +CREATE INDEX `message_trace_id_idx` ON `message` (`trace_id`);--> statement-breakpoint +CREATE TABLE `preference` ( + `scope` text DEFAULT 'default' NOT NULL, + `key` text NOT NULL, + `value` text, + `created_at` integer, + `updated_at` integer, + PRIMARY KEY(`scope`, `key`) +); +--> statement-breakpoint +CREATE TABLE `tag` ( + `id` text PRIMARY KEY NOT NULL, + `name` text NOT NULL, + `color` text, + `created_at` integer, + `updated_at` integer +); +--> statement-breakpoint +CREATE UNIQUE INDEX `tag_name_unique` ON `tag` (`name`);--> statement-breakpoint +CREATE TABLE `topic` ( + `id` text PRIMARY KEY NOT NULL, + `name` text, + `assistant_id` text, + `assistant_meta` text, + `prompt` text, + `group_id` text, + `is_pinned` integer DEFAULT false, + `pinned_order` integer DEFAULT 0, + `sort_order` integer DEFAULT 0, + `is_name_manually_edited` integer DEFAULT false, + `created_at` integer, + `updated_at` integer, + `deleted_at` integer, + FOREIGN KEY (`group_id`) REFERENCES `group`(`id`) ON UPDATE no action ON DELETE set null +); +--> statement-breakpoint +CREATE INDEX `topic_group_updated_idx` ON `topic` (`group_id`,`updated_at`);--> statement-breakpoint +CREATE INDEX `topic_group_sort_idx` ON `topic` (`group_id`,`sort_order`);--> statement-breakpoint +CREATE INDEX `topic_updated_at_idx` ON `topic` (`updated_at`);--> statement-breakpoint +CREATE INDEX `topic_is_pinned_idx` ON `topic` (`is_pinned`,`pinned_order`);--> statement-breakpoint +CREATE INDEX `topic_assistant_id_idx` ON `topic` (`assistant_id`); +--> statement-breakpoint +-- ============================================================ +-- FTS5 Virtual Table and Triggers for Message Full-Text Search +-- ============================================================ + +-- 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 + +-- 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 + +-- 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; \ No newline at end of file diff --git a/migrations/sqlite-drizzle/0000_solid_lord_hawal.sql b/migrations/sqlite-drizzle/0000_solid_lord_hawal.sql deleted file mode 100644 index 9e52692966..0000000000 --- a/migrations/sqlite-drizzle/0000_solid_lord_hawal.sql +++ /dev/null @@ -1,17 +0,0 @@ -CREATE TABLE `app_state` ( - `key` text PRIMARY KEY NOT NULL, - `value` text NOT NULL, - `description` text, - `created_at` integer, - `updated_at` integer -); ---> statement-breakpoint -CREATE TABLE `preference` ( - `scope` text NOT NULL, - `key` text NOT NULL, - `value` text, - `created_at` integer, - `updated_at` integer -); ---> statement-breakpoint -CREATE INDEX `scope_name_idx` ON `preference` (`scope`,`key`); \ No newline at end of file diff --git a/migrations/sqlite-drizzle/meta/0000_snapshot.json b/migrations/sqlite-drizzle/meta/0000_snapshot.json index 51c5ed6cba..eb3f54f553 100644 --- a/migrations/sqlite-drizzle/meta/0000_snapshot.json +++ b/migrations/sqlite-drizzle/meta/0000_snapshot.json @@ -1,114 +1,612 @@ { - "_meta": { - "columns": {}, - "schemas": {}, - "tables": {} - }, + "version": "6", "dialect": "sqlite", - "enums": {}, - "id": "de8009d7-95b9-4f99-99fa-4b8795708f21", - "internal": { - "indexes": {} - }, + "id": "62a198e0-bfc2-4db1-af58-7e479fedd7b9", "prevId": "00000000-0000-0000-0000-000000000000", "tables": { "app_state": { - "checkConstraints": {}, + "name": "app_state", "columns": { - "created_at": { - "autoincrement": false, - "name": "created_at", - "notNull": false, + "key": { + "name": "key", + "type": "text", + "primaryKey": true, + "notNull": true, + "autoincrement": false + }, + "value": { + "name": "value", + "type": "text", "primaryKey": false, - "type": "integer" + "notNull": true, + "autoincrement": false }, "description": { - "autoincrement": false, "name": "description", - "notNull": false, + "type": "text", "primaryKey": false, - "type": "text" + "notNull": false, + "autoincrement": false }, - "key": { - "autoincrement": false, - "name": "key", - "notNull": true, - "primaryKey": true, - "type": "text" + "created_at": { + "name": "created_at", + "type": "integer", + "primaryKey": false, + "notNull": false, + "autoincrement": false }, "updated_at": { - "autoincrement": false, "name": "updated_at", + "type": "integer", + "primaryKey": false, "notNull": false, + "autoincrement": false + } + }, + "indexes": {}, + "foreignKeys": {}, + "compositePrimaryKeys": {}, + "uniqueConstraints": {}, + "checkConstraints": {} + }, + "entity_tag": { + "name": "entity_tag", + "columns": { + "entity_type": { + "name": "entity_type", + "type": "text", "primaryKey": false, - "type": "integer" - }, - "value": { - "autoincrement": false, - "name": "value", "notNull": true, + "autoincrement": false + }, + "entity_id": { + "name": "entity_id", + "type": "text", "primaryKey": false, - "type": "text" + "notNull": true, + "autoincrement": false + }, + "tag_id": { + "name": "tag_id", + "type": "text", + "primaryKey": false, + "notNull": true, + "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 + } + }, + "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" + } + }, + "compositePrimaryKeys": { + "entity_tag_entity_type_entity_id_tag_id_pk": { + "columns": ["entity_type", "entity_id", "tag_id"], + "name": "entity_tag_entity_type_entity_id_tag_id_pk" + } + }, + "uniqueConstraints": {}, + "checkConstraints": {} + }, + "group": { + "name": "group", + "columns": { + "id": { + "name": "id", + "type": "text", + "primaryKey": true, + "notNull": true, + "autoincrement": false + }, + "entity_type": { + "name": "entity_type", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "name": { + "name": "name", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "sort_order": { + "name": "sort_order", + "type": "integer", + "primaryKey": false, + "notNull": false, + "autoincrement": false, + "default": 0 + }, + "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 + } + }, + "indexes": { + "group_entity_sort_idx": { + "name": "group_entity_sort_idx", + "columns": ["entity_type", "sort_order"], + "isUnique": false + } + }, + "foreignKeys": {}, + "compositePrimaryKeys": {}, + "uniqueConstraints": {}, + "checkConstraints": {} + }, + "message": { + "name": "message", + "columns": { + "id": { + "name": "id", + "type": "text", + "primaryKey": true, + "notNull": true, + "autoincrement": false + }, + "topic_id": { + "name": "topic_id", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "parent_id": { + "name": "parent_id", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "response_group_id": { + "name": "response_group_id", + "type": "integer", + "primaryKey": false, + "notNull": false, + "autoincrement": false, + "default": 0 + }, + "role": { + "name": "role", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "status": { + "name": "status", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "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 + }, + "data": { + "name": "data", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "usage": { + "name": "usage", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "metrics": { + "name": "metrics", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "trace_id": { + "name": "trace_id", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "searchable_text": { + "name": "searchable_text", + "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": {}, - "foreignKeys": {}, - "indexes": {}, - "name": "app_state", - "uniqueConstraints": {} + "uniqueConstraints": {}, + "checkConstraints": { + "message_role_check": { + "name": "message_role_check", + "value": "\"message\".\"role\" IN ('user', 'assistant', 'system')" + }, + "message_status_check": { + "name": "message_status_check", + "value": "\"message\".\"status\" IN ('success', 'error', 'paused')" + } + } }, "preference": { - "checkConstraints": {}, + "name": "preference", "columns": { - "created_at": { - "autoincrement": false, - "name": "created_at", - "notNull": false, + "scope": { + "name": "scope", + "type": "text", "primaryKey": false, - "type": "integer" + "notNull": true, + "autoincrement": false, + "default": "'default'" }, "key": { - "autoincrement": false, "name": "key", + "type": "text", + "primaryKey": false, "notNull": true, - "primaryKey": false, - "type": "text" - }, - "scope": { - "autoincrement": false, - "name": "scope", - "notNull": true, - "primaryKey": false, - "type": "text" - }, - "updated_at": { - "autoincrement": false, - "name": "updated_at", - "notNull": false, - "primaryKey": false, - "type": "integer" + "autoincrement": false }, "value": { - "autoincrement": false, "name": "value", - "notNull": false, + "type": "text", "primaryKey": false, - "type": "text" + "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 + } + }, + "indexes": {}, + "foreignKeys": {}, + "compositePrimaryKeys": { + "preference_scope_key_pk": { + "columns": ["scope", "key"], + "name": "preference_scope_key_pk" + } + }, + "uniqueConstraints": {}, + "checkConstraints": {} + }, + "tag": { + "name": "tag", + "columns": { + "id": { + "name": "id", + "type": "text", + "primaryKey": true, + "notNull": true, + "autoincrement": false + }, + "name": { + "name": "name", + "type": "text", + "primaryKey": false, + "notNull": true, + "autoincrement": false + }, + "color": { + "name": "color", + "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 + } + }, + "indexes": { + "tag_name_unique": { + "name": "tag_name_unique", + "columns": ["name"], + "isUnique": true + } + }, + "foreignKeys": {}, + "compositePrimaryKeys": {}, + "uniqueConstraints": {}, + "checkConstraints": {} + }, + "topic": { + "name": "topic", + "columns": { + "id": { + "name": "id", + "type": "text", + "primaryKey": true, + "notNull": true, + "autoincrement": false + }, + "name": { + "name": "name", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "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 + }, + "prompt": { + "name": "prompt", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "group_id": { + "name": "group_id", + "type": "text", + "primaryKey": false, + "notNull": false, + "autoincrement": false + }, + "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 + }, + "sort_order": { + "name": "sort_order", + "type": "integer", + "primaryKey": false, + "notNull": false, + "autoincrement": false, + "default": 0 + }, + "is_name_manually_edited": { + "name": "is_name_manually_edited", + "type": "integer", + "primaryKey": false, + "notNull": false, + "autoincrement": false, + "default": 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": { + "topic_group_updated_idx": { + "name": "topic_group_updated_idx", + "columns": ["group_id", "updated_at"], + "isUnique": false + }, + "topic_group_sort_idx": { + "name": "topic_group_sort_idx", + "columns": ["group_id", "sort_order"], + "isUnique": false + }, + "topic_updated_at_idx": { + "name": "topic_updated_at_idx", + "columns": ["updated_at"], + "isUnique": false + }, + "topic_is_pinned_idx": { + "name": "topic_is_pinned_idx", + "columns": ["is_pinned", "pinned_order"], + "isUnique": false + }, + "topic_assistant_id_idx": { + "name": "topic_assistant_id_idx", + "columns": ["assistant_id"], + "isUnique": false + } + }, + "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": {}, - "foreignKeys": {}, - "indexes": { - "scope_name_idx": { - "columns": ["scope", "key"], - "isUnique": false, - "name": "scope_name_idx" - } - }, - "name": "preference", - "uniqueConstraints": {} + "uniqueConstraints": {}, + "checkConstraints": {} } }, - "version": "6", - "views": {} + "views": {}, + "enums": {}, + "_meta": { + "schemas": {}, + "tables": {}, + "columns": {} + }, + "internal": { + "indexes": {} + } } diff --git a/migrations/sqlite-drizzle/meta/_journal.json b/migrations/sqlite-drizzle/meta/_journal.json index db2791fd7f..781e2d3d99 100644 --- a/migrations/sqlite-drizzle/meta/_journal.json +++ b/migrations/sqlite-drizzle/meta/_journal.json @@ -1,13 +1,13 @@ { + "version": "7", "dialect": "sqlite", "entries": [ { - "breakpoints": true, "idx": 0, - "tag": "0000_solid_lord_hawal", "version": "6", - "when": 1754745234572 + "when": 1766588456958, + "tag": "0000_init", + "breakpoints": true } - ], - "version": "7" + ] } diff --git a/src/main/data/db/schemas/entityTag.ts b/src/main/data/db/schemas/entityTag.ts new file mode 100644 index 0000000000..e041d771db --- /dev/null +++ b/src/main/data/db/schemas/entityTag.ts @@ -0,0 +1,26 @@ +import { index, primaryKey, sqliteTable, text } from 'drizzle-orm/sqlite-core' + +import { createUpdateTimestamps } from './columnHelpers' +import { tagTable } from './tag' + +/** + * Entity-Tag join table - associates tags with entities + * + * Supports many-to-many relationship between tags and + * various entity types (topic, session, assistant). + */ +export const entityTagTable = sqliteTable( + 'entity_tag', + { + // Entity type: topic, session, assistant + entityType: text().notNull(), + // FK to the entity + entityId: text().notNull(), + // FK to tag table - CASCADE: delete association when tag is deleted + tagId: text() + .notNull() + .references(() => tagTable.id, { onDelete: 'cascade' }), + ...createUpdateTimestamps + }, + (t) => [primaryKey({ columns: [t.entityType, t.entityId, t.tagId] }), index('entity_tag_tag_id_idx').on(t.tagId)] +) diff --git a/src/main/data/db/schemas/group.ts b/src/main/data/db/schemas/group.ts new file mode 100644 index 0000000000..dc7bd088c2 --- /dev/null +++ b/src/main/data/db/schemas/group.ts @@ -0,0 +1,24 @@ +import { index, integer, sqliteTable, text } from 'drizzle-orm/sqlite-core' + +import { createUpdateTimestamps } from './columnHelpers' + +/** + * Group table - general-purpose grouping for entities + * + * Supports grouping of topics, sessions, and assistants. + * Each group belongs to a specific entity type. + */ +export const groupTable = sqliteTable( + 'group', + { + id: text().primaryKey(), + // Entity type this group belongs to: topic, session, assistant + entityType: text().notNull(), + // Display name of the group + name: text().notNull(), + // Sort order for display + sortOrder: integer().default(0), + ...createUpdateTimestamps + }, + (t) => [index('group_entity_sort_idx').on(t.entityType, t.sortOrder)] +) diff --git a/src/main/data/db/schemas/message.ts b/src/main/data/db/schemas/message.ts new file mode 100644 index 0000000000..d5a644bcce --- /dev/null +++ b/src/main/data/db/schemas/message.ts @@ -0,0 +1,60 @@ +import { sql } from 'drizzle-orm' +import { check, index, integer, sqliteTable, text } from 'drizzle-orm/sqlite-core' + +import { createUpdateDeleteTimestamps } from './columnHelpers' +import { topicTable } from './topic' + +/** + * Message table - stores chat messages with tree structure + * + * Uses adjacency list pattern (parentId) for tree navigation. + * Block content is stored as JSON in the data field. + * searchableText is a generated column for FTS5 indexing. + */ +export const messageTable = sqliteTable( + 'message', + { + id: text().primaryKey(), + // FK to topic - CASCADE: delete messages when topic is deleted + topicId: text() + .notNull() + .references(() => topicTable.id, { onDelete: 'cascade' }), + // Adjacency list parent reference for tree structure + // SET NULL: preserve child messages when parent is deleted + parentId: text().references(() => messageTable.id, { onDelete: 'set null' }), + // Group ID for multi-model responses (0 = normal branch) + responseGroupId: integer().default(0), + // Message role: user, assistant, system + role: text().notNull(), + // Final status: SUCCESS, ERROR, PAUSED + status: text().notNull(), + // FK to assistant + assistantId: text(), + // Preserved assistant info for display + assistantMeta: text({ mode: 'json' }), + // Model identifier + modelId: text(), + // Preserved model info (provider, name) + modelMeta: text({ mode: 'json' }), + // Main content - contains blocks[], mentions, etc. + data: text({ mode: 'json' }).notNull(), + // Token usage statistics + usage: text({ mode: 'json' }), + // Performance metrics + metrics: text({ mode: 'json' }), + // Trace ID for tracking + traceId: text(), + // Searchable text extracted from data.blocks (populated by trigger, used for FTS5) + searchableText: text(), + ...createUpdateDeleteTimestamps + }, + (t) => [ + // Indexes + index('message_parent_id_idx').on(t.parentId), + index('message_topic_created_idx').on(t.topicId, t.createdAt), + index('message_trace_id_idx').on(t.traceId), + // Check constraints for enum fields + check('message_role_check', sql`${t.role} IN ('user', 'assistant', 'system')`), + check('message_status_check', sql`${t.status} IN ('success', 'error', 'paused')`) + ] +) diff --git a/src/main/data/db/schemas/messageFts.ts b/src/main/data/db/schemas/messageFts.ts new file mode 100644 index 0000000000..e87bcf0010 --- /dev/null +++ b/src/main/data/db/schemas/messageFts.ts @@ -0,0 +1,94 @@ +/** + * FTS5 SQL statements for message full-text search + * + * This file contains SQL statements that must be manually added to migration files. + * Drizzle does not auto-generate virtual tables or triggers. + * + * Architecture: + * 1. message.searchable_text - regular column populated by trigger + * 2. message_fts - FTS5 virtual table with external content + * 3. Triggers sync both searchable_text and FTS5 index + * + * Usage: + * - Copy MESSAGE_FTS_MIGRATION_SQL to migration file when generating migrations + */ + +/** + * SQL expression to extract searchable text from data.blocks + * Concatenates content from all main_text type blocks + */ +export const SEARCHABLE_TEXT_EXPRESSION = ` + (SELECT group_concat(json_extract(value, '$.content'), ' ') + FROM json_each(json_extract(NEW.data, '$.blocks')) + WHERE json_extract(value, '$.type') = 'main_text') +` + +/** + * Migration SQL - Copy these statements to migration file + */ +export const MESSAGE_FTS_MIGRATION_SQL = ` +--> statement-breakpoint +-- ============================================================ +-- FTS5 Virtual Table and Triggers for Message Full-Text Search +-- ============================================================ + +-- 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 + +-- 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 + +-- 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; +` + +/** + * Rebuild FTS index (run manually if needed) + */ +export const REBUILD_FTS_SQL = `INSERT INTO message_fts(message_fts) VALUES ('rebuild')` + +/** + * Example search query + */ +export const EXAMPLE_SEARCH_SQL = ` +SELECT m.* +FROM message m +JOIN message_fts fts ON m.rowid = fts.rowid +WHERE message_fts MATCH ? +ORDER BY rank +` diff --git a/src/main/data/db/schemas/preference.ts b/src/main/data/db/schemas/preference.ts index f41cf175c4..5ca9b2f14a 100644 --- a/src/main/data/db/schemas/preference.ts +++ b/src/main/data/db/schemas/preference.ts @@ -1,14 +1,14 @@ -import { index, sqliteTable, text } from 'drizzle-orm/sqlite-core' +import { primaryKey, sqliteTable, text } from 'drizzle-orm/sqlite-core' import { createUpdateTimestamps } from './columnHelpers' export const preferenceTable = sqliteTable( 'preference', { - scope: text().notNull(), // scope is reserved for future use, now only 'default' is supported + scope: text().notNull().default('default'), // scope is reserved for future use, now only 'default' is supported key: text().notNull(), value: text({ mode: 'json' }), ...createUpdateTimestamps }, - (t) => [index('scope_name_idx').on(t.scope, t.key)] + (t) => [primaryKey({ columns: [t.scope, t.key] })] ) diff --git a/src/main/data/db/schemas/tag.ts b/src/main/data/db/schemas/tag.ts new file mode 100644 index 0000000000..8a84e6d704 --- /dev/null +++ b/src/main/data/db/schemas/tag.ts @@ -0,0 +1,18 @@ +import { sqliteTable, text } from 'drizzle-orm/sqlite-core' + +import { createUpdateTimestamps } from './columnHelpers' + +/** + * Tag table - general-purpose tags for entities + * + * Tags can be applied to topics, sessions, and assistants + * via the entity_tag join table. + */ +export const tagTable = sqliteTable('tag', { + id: text().primaryKey(), + // Unique tag name + name: text().notNull().unique(), + // Display color (hex code) + color: text(), + ...createUpdateTimestamps +}) diff --git a/src/main/data/db/schemas/topic.ts b/src/main/data/db/schemas/topic.ts new file mode 100644 index 0000000000..2f08d58fd2 --- /dev/null +++ b/src/main/data/db/schemas/topic.ts @@ -0,0 +1,41 @@ +import { index, integer, sqliteTable, text } from 'drizzle-orm/sqlite-core' + +import { createUpdateDeleteTimestamps } from './columnHelpers' +import { groupTable } from './group' + +/** + * Topic table - stores conversation topics/threads + * + * Topics are containers for messages and belong to assistants. + * They can be organized into groups and have tags for categorization. + */ +export const topicTable = sqliteTable( + 'topic', + { + id: text().primaryKey(), + name: text(), + assistantId: text(), + // Preserved assistant info for display when assistant is deleted + assistantMeta: text({ mode: 'json' }), + // Topic-specific prompt override + prompt: text(), + // FK to group table for organization + // SET NULL: preserve topic when group is deleted + groupId: text().references(() => groupTable.id, { onDelete: 'set null' }), + // Pinning state and order + isPinned: integer({ mode: 'boolean' }).default(false), + pinnedOrder: integer().default(0), + // Sort order within group + sortOrder: integer().default(0), + // Whether the name was manually edited by user + isNameManuallyEdited: integer({ mode: 'boolean' }).default(false), + ...createUpdateDeleteTimestamps + }, + (t) => [ + index('topic_group_updated_idx').on(t.groupId, t.updatedAt), + index('topic_group_sort_idx').on(t.groupId, t.sortOrder), + index('topic_updated_at_idx').on(t.updatedAt), + index('topic_is_pinned_idx').on(t.isPinned, t.pinnedOrder), + index('topic_assistant_id_idx').on(t.assistantId) + ] +)