import sqlite3 from 'node-sqlite3-wasm'; type Database = sqlite3.Database; /** * SQLite schema based on the MySQL erit_main_db schema * All tables use snake_case naming to match the server database * Data is encrypted before storage and decrypted on retrieval */ export const SCHEMA_VERSION = 2; /** * Initialize the local SQLite database with all required tables * @param db - SQLite database instance */ export function initializeSchema(db: Database): void { // Enable foreign keys db.exec('PRAGMA foreign_keys = ON'); // AI Conversations db.exec(` CREATE TABLE IF NOT EXISTS ai_conversations ( conversation_id TEXT PRIMARY KEY, book_id TEXT NOT NULL, mode TEXT NOT NULL, title TEXT NOT NULL, start_date INTEGER NOT NULL, status INTEGER NOT NULL, user_id TEXT NOT NULL, summary TEXT, convo_meta TEXT NOT NULL, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // AI Messages History db.exec(` CREATE TABLE IF NOT EXISTS ai_messages_history ( message_id TEXT PRIMARY KEY, conversation_id TEXT NOT NULL, role TEXT NOT NULL, message TEXT NOT NULL, message_date INTEGER NOT NULL, FOREIGN KEY (conversation_id) REFERENCES ai_conversations(conversation_id) ON DELETE CASCADE ); `); // Book Acts db.exec(` CREATE TABLE IF NOT EXISTS book_acts ( act_id INTEGER PRIMARY KEY, title TEXT NOT NULL, last_update INTEGER DEFAULT 0 ); `); // Book Act Summaries db.exec(` CREATE TABLE IF NOT EXISTS book_act_summaries ( act_sum_id TEXT PRIMARY KEY, book_id TEXT NOT NULL, user_id TEXT NOT NULL, act_index INTEGER NOT NULL, summary TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book AI Guide Line db.exec(` CREATE TABLE IF NOT EXISTS book_ai_guide_line ( user_id TEXT NOT NULL, book_id TEXT NOT NULL, global_resume TEXT, themes TEXT, verbe_tense INTEGER, narrative_type INTEGER, langue INTEGER, dialogue_type INTEGER, tone TEXT, atmosphere TEXT, current_resume TEXT, last_update INTEGER DEFAULT 0, PRIMARY KEY (user_id, book_id), FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Chapters db.exec(` CREATE TABLE IF NOT EXISTS book_chapters ( chapter_id TEXT PRIMARY KEY, book_id TEXT NOT NULL, author_id TEXT NOT NULL, title TEXT NOT NULL, hashed_title TEXT, words_count INTEGER, chapter_order INTEGER, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Chapter Content db.exec(` CREATE TABLE IF NOT EXISTS book_chapter_content ( content_id TEXT PRIMARY KEY, chapter_id TEXT NOT NULL, author_id TEXT NOT NULL, version INTEGER NOT NULL DEFAULT 2, content TEXT, words_count INTEGER NOT NULL, time_on_it INTEGER NOT NULL DEFAULT 0, last_update INTEGER DEFAULT 0, FOREIGN KEY (chapter_id) REFERENCES book_chapters(chapter_id) ON DELETE CASCADE ); `); // Book Chapter Infos db.exec(` CREATE TABLE IF NOT EXISTS book_chapter_infos ( chapter_info_id TEXT PRIMARY KEY, chapter_id TEXT, act_id INTEGER, incident_id TEXT, plot_point_id TEXT, book_id TEXT, author_id TEXT, summary TEXT, goal TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (chapter_id) REFERENCES book_chapters(chapter_id) ON DELETE CASCADE, FOREIGN KEY (incident_id) REFERENCES book_incidents(incident_id) ON DELETE CASCADE, FOREIGN KEY (plot_point_id) REFERENCES book_plot_points(plot_point_id) ON DELETE CASCADE ); `); // Book Characters db.exec(` CREATE TABLE IF NOT EXISTS book_characters ( character_id TEXT PRIMARY KEY, book_id TEXT NOT NULL, user_id TEXT NOT NULL, first_name TEXT NOT NULL, last_name TEXT, category TEXT NOT NULL, title TEXT, image TEXT, role TEXT, biography TEXT, history TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Character Attributes db.exec(` CREATE TABLE IF NOT EXISTS book_characters_attributes ( attr_id TEXT PRIMARY KEY, character_id TEXT NOT NULL, user_id TEXT NOT NULL, attribute_name TEXT NOT NULL, attribute_value TEXT NOT NULL, last_update INTEGER DEFAULT 0, FOREIGN KEY (character_id) REFERENCES book_characters(character_id) ON DELETE CASCADE ); `); // Book Character Relations db.exec(` CREATE TABLE IF NOT EXISTS book_characters_relations ( rel_id INTEGER PRIMARY KEY, character_id INTEGER NOT NULL, char_name TEXT NOT NULL, type TEXT NOT NULL, description TEXT NOT NULL, history TEXT NOT NULL, last_update INTEGER DEFAULT 0 ); `); // Book Guide Line db.exec(` CREATE TABLE IF NOT EXISTS book_guide_line ( user_id TEXT NOT NULL, book_id TEXT NOT NULL, tone TEXT, atmosphere TEXT, writing_style TEXT, themes TEXT, symbolism TEXT, motifs TEXT, narrative_voice TEXT, pacing TEXT, intended_audience TEXT, key_messages TEXT, last_update INTEGER DEFAULT 0, PRIMARY KEY (user_id, book_id), FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Incidents db.exec(` CREATE TABLE IF NOT EXISTS book_incidents ( incident_id TEXT PRIMARY KEY, author_id TEXT NOT NULL, book_id TEXT NOT NULL, title TEXT NOT NULL, hashed_title TEXT NOT NULL, summary TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Issues db.exec(` CREATE TABLE IF NOT EXISTS book_issues ( issue_id TEXT PRIMARY KEY, author_id TEXT NOT NULL, book_id TEXT NOT NULL, name TEXT NOT NULL, hashed_issue_name TEXT NOT NULL, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Location db.exec(` CREATE TABLE IF NOT EXISTS book_location ( loc_id TEXT PRIMARY KEY, book_id TEXT NOT NULL, user_id TEXT NOT NULL, loc_name TEXT NOT NULL, loc_original_name TEXT NOT NULL, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book Plot Points db.exec(` CREATE TABLE IF NOT EXISTS book_plot_points ( plot_point_id TEXT PRIMARY KEY, title TEXT NOT NULL, hashed_title TEXT NOT NULL, summary TEXT, linked_incident_id TEXT, author_id TEXT NOT NULL, book_id TEXT NOT NULL, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book World db.exec(` CREATE TABLE IF NOT EXISTS book_world ( world_id TEXT PRIMARY KEY, name TEXT NOT NULL, hashed_name TEXT NOT NULL, author_id TEXT NOT NULL, book_id TEXT NOT NULL, history TEXT, politics TEXT, economy TEXT, religion TEXT, languages TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE ); `); // Book World Elements db.exec(` CREATE TABLE IF NOT EXISTS book_world_elements ( element_id TEXT PRIMARY KEY, world_id TEXT NOT NULL, user_id TEXT NOT NULL, element_type INTEGER NOT NULL, name TEXT NOT NULL, original_name TEXT NOT NULL, description TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (world_id) REFERENCES book_world(world_id) ON DELETE CASCADE ); `); // Erit Books db.exec(` CREATE TABLE IF NOT EXISTS erit_books ( book_id TEXT PRIMARY KEY, type TEXT NOT NULL, author_id TEXT NOT NULL, title TEXT NOT NULL, hashed_title TEXT NOT NULL, sub_title TEXT, hashed_sub_title TEXT, summary TEXT, serie_id INTEGER, desired_release_date TEXT, desired_word_count INTEGER, words_count INTEGER, cover_image TEXT, last_update INTEGER DEFAULT 0 ); `); // Erit Book Series db.exec(` CREATE TABLE IF NOT EXISTS erit_book_series ( serie_id INTEGER PRIMARY KEY, name TEXT NOT NULL, author_id INTEGER NOT NULL ); `); // Erit Editor Settings db.exec(` CREATE TABLE IF NOT EXISTS erit_editor ( user_id TEXT, type TEXT NOT NULL, text_size INTEGER NOT NULL, text_intent INTEGER NOT NULL, interline TEXT NOT NULL, paper_width INTEGER NOT NULL, theme TEXT NOT NULL, focus INTEGER NOT NULL ); `); // Erit Users db.exec(` CREATE TABLE IF NOT EXISTS erit_users ( user_id TEXT PRIMARY KEY, first_name TEXT NOT NULL, last_name TEXT NOT NULL, username TEXT NOT NULL, email TEXT NOT NULL, origin_email TEXT NOT NULL, origin_username TEXT NOT NULL, author_name TEXT, origin_author_name TEXT, plateform TEXT NOT NULL, social_id TEXT, user_group INTEGER NOT NULL DEFAULT 4, password TEXT, term_accepted INTEGER NOT NULL DEFAULT 0, verify_code TEXT, reg_date INTEGER NOT NULL, account_verified INTEGER NOT NULL DEFAULT 0, erite_points INTEGER NOT NULL DEFAULT 100, stripe_customer_id TEXT, credits_balance REAL DEFAULT 0 ); `); // Location Element db.exec(` CREATE TABLE IF NOT EXISTS location_element ( element_id TEXT PRIMARY KEY, location TEXT NOT NULL, user_id TEXT NOT NULL, element_name TEXT NOT NULL, original_name TEXT NOT NULL, element_description TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (location) REFERENCES book_location(loc_id) ON DELETE CASCADE ); `); // Location Sub Element db.exec(` CREATE TABLE IF NOT EXISTS location_sub_element ( sub_element_id TEXT PRIMARY KEY, element_id TEXT NOT NULL, user_id TEXT NOT NULL, sub_elem_name TEXT NOT NULL, original_name TEXT NOT NULL, sub_elem_description TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (element_id) REFERENCES location_element(element_id) ON DELETE CASCADE ); `); // User Keys db.exec(` CREATE TABLE IF NOT EXISTS user_keys ( user_id TEXT NOT NULL, brand TEXT NOT NULL, key TEXT NOT NULL, actif INTEGER NOT NULL DEFAULT 1, FOREIGN KEY (user_id) REFERENCES erit_users(user_id) ON DELETE CASCADE ); `); // User Last Chapter db.exec(` CREATE TABLE IF NOT EXISTS user_last_chapter ( user_id TEXT NOT NULL, book_id TEXT NOT NULL, chapter_id TEXT NOT NULL, version INTEGER NOT NULL, PRIMARY KEY (user_id, book_id), FOREIGN KEY (book_id) REFERENCES erit_books(book_id) ON DELETE CASCADE, FOREIGN KEY (chapter_id) REFERENCES book_chapters(chapter_id) ON DELETE CASCADE ); `); // Create indexes for better performance createIndexes(db); // Set schema version for new databases (prevents unnecessary migrations) initializeSchemaVersion(db); } /** * Create indexes for frequently queried columns */ function createIndexes(db: Database): void { db.exec(` CREATE INDEX IF NOT EXISTS idx_ai_conversations_book ON ai_conversations(book_id); CREATE INDEX IF NOT EXISTS idx_ai_conversations_user ON ai_conversations(user_id); CREATE INDEX IF NOT EXISTS idx_ai_messages_conversation ON ai_messages_history(conversation_id); CREATE INDEX IF NOT EXISTS idx_chapters_book ON book_chapters(book_id); CREATE INDEX IF NOT EXISTS idx_chapter_content_chapter ON book_chapter_content(chapter_id); CREATE INDEX IF NOT EXISTS idx_characters_book ON book_characters(book_id); CREATE INDEX IF NOT EXISTS idx_character_attrs_character ON book_characters_attributes(character_id); CREATE INDEX IF NOT EXISTS idx_world_book ON book_world(book_id); CREATE INDEX IF NOT EXISTS idx_world_elements_world ON book_world_elements(world_id); `); } /** * Get current schema version from database */ function getDbSchemaVersion(db: Database): number { try { const result = db.get('SELECT version FROM _schema_version LIMIT 1') as { version: number } | undefined; return result?.version ?? 0; } catch { return 0; } } /** * Set schema version in database */ function setDbSchemaVersion(db: Database, version: number): void { db.exec('CREATE TABLE IF NOT EXISTS _schema_version (version INTEGER PRIMARY KEY)'); db.run('DELETE FROM _schema_version'); db.run('INSERT INTO _schema_version (version) VALUES (?)', [version]); } /** * Initialize schema version for new databases * Only sets version if table doesn't exist yet (new DB) */ function initializeSchemaVersion(db: Database): void { const currentVersion = getDbSchemaVersion(db); if (currentVersion === 0) { setDbSchemaVersion(db, SCHEMA_VERSION); } } /** * Check if a column exists in a table */ function columnExists(db: Database, tableName: string, columnName: string): boolean { const columns = db.all(`PRAGMA table_info(${tableName})`) as { name: string }[]; return columns.some(col => col.name === columnName); } /** * Safely drop a column if it exists */ function dropColumnIfExists(db: Database, tableName: string, columnName: string): void { if (columnExists(db, tableName, columnName)) { try { db.exec(`ALTER TABLE ${tableName} DROP COLUMN ${columnName}`); } catch (e) { console.error(`[Migration] Failed to drop column ${columnName} from ${tableName}:`, e); } } } /** * Recreate a table with a new schema while preserving data */ function recreateTable(db: Database, tableName: string, newSchema: string, columnsToKeep: string): void { try { db.exec('PRAGMA foreign_keys = OFF'); db.exec(`CREATE TABLE ${tableName}_backup AS SELECT ${columnsToKeep} FROM ${tableName}`); db.exec(`DROP TABLE ${tableName}`); db.exec(newSchema); db.exec(`INSERT INTO ${tableName} (${columnsToKeep}) SELECT ${columnsToKeep} FROM ${tableName}_backup`); db.exec(`DROP TABLE ${tableName}_backup`); db.exec('PRAGMA foreign_keys = ON'); } catch (e) { console.error(`[Migration] Failed to recreate table ${tableName}:`, e); db.exec('PRAGMA foreign_keys = ON'); } } /** * Run migrations to update schema from one version to another */ export function runMigrations(db: Database): void { const currentVersion = getDbSchemaVersion(db); if (currentVersion >= SCHEMA_VERSION) { return; } // Migration v2: Remove NOT NULL constraints to allow null values from server sync if (currentVersion < 2) { // Recreate erit_books with nullable hashed_sub_title and summary recreateTable(db, 'erit_books', ` CREATE TABLE erit_books ( book_id TEXT PRIMARY KEY, type TEXT NOT NULL, author_id TEXT NOT NULL, title TEXT NOT NULL, hashed_title TEXT NOT NULL, sub_title TEXT, hashed_sub_title TEXT, summary TEXT, serie_id INTEGER, desired_release_date TEXT, desired_word_count INTEGER, words_count INTEGER, cover_image TEXT, last_update INTEGER DEFAULT 0 ) `, 'book_id, type, author_id, title, hashed_title, sub_title, hashed_sub_title, summary, serie_id, desired_release_date, desired_word_count, words_count, cover_image, last_update'); // Recreate book_chapter_content with nullable content recreateTable(db, 'book_chapter_content', ` CREATE TABLE book_chapter_content ( content_id TEXT PRIMARY KEY, chapter_id TEXT NOT NULL, author_id TEXT NOT NULL, version INTEGER NOT NULL DEFAULT 2, content TEXT, words_count INTEGER NOT NULL, time_on_it INTEGER NOT NULL DEFAULT 0, last_update INTEGER DEFAULT 0, FOREIGN KEY (chapter_id) REFERENCES book_chapters(chapter_id) ON DELETE CASCADE ) `, 'content_id, chapter_id, author_id, version, content, words_count, time_on_it, last_update'); // Recreate book_chapter_infos with nullable summary and goal recreateTable(db, 'book_chapter_infos', ` CREATE TABLE book_chapter_infos ( chapter_info_id TEXT PRIMARY KEY, chapter_id TEXT, act_id INTEGER, incident_id TEXT, plot_point_id TEXT, book_id TEXT, author_id TEXT, summary TEXT, goal TEXT, last_update INTEGER DEFAULT 0, FOREIGN KEY (chapter_id) REFERENCES book_chapters(chapter_id) ON DELETE CASCADE, FOREIGN KEY (incident_id) REFERENCES book_incidents(incident_id) ON DELETE CASCADE, FOREIGN KEY (plot_point_id) REFERENCES book_plot_points(plot_point_id) ON DELETE CASCADE ) `, 'chapter_info_id, chapter_id, act_id, incident_id, plot_point_id, book_id, author_id, summary, goal, last_update'); } // Update schema version setDbSchemaVersion(db, SCHEMA_VERSION); }