mirror of
https://github.com/CherryHQ/cherry-studio.git
synced 2026-01-12 08:59:02 +08:00
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.
This commit is contained in:
parent
b1de7283dc
commit
3dfd5c7c2b
@ -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.
|
||||
|
||||
File diff suppressed because it is too large
Load Diff
@ -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"
|
||||
}
|
||||
}
|
||||
|
||||
@ -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<void> {
|
||||
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
|
||||
|
||||
@ -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
|
||||
|
||||
25
src/main/data/db/customSql.ts
Normal file
25
src/main/data/db/customSql.ts
Normal file
@ -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
|
||||
]
|
||||
@ -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)
|
||||
|
||||
Loading…
Reference in New Issue
Block a user