From ebef5d6c8d802517b110d6f9bfcf7a14afbc853b Mon Sep 17 00:00:00 2001 From: Matthew Raymer Date: Sat, 31 May 2025 12:54:55 +0000 Subject: [PATCH] feat(sqlite): Initialize database with complete schema and PRAGMAs Initial database setup with: - Created database at /home/matthew/Databases/TimeSafari/timesafariSQLite.db - Set optimized PRAGMAs for performance and safety: * WAL journal mode for better concurrency * Foreign key constraints enabled * Normal synchronous mode * Memory temp store * 4KB page size * 2000 page cache (8MB) - Created core tables: * schema_version (for migration tracking) * users (for user management) * time_entries (for time tracking) * time_goals (for goal setting) * time_goal_entries (for goal tracking) - Added automatic timestamp triggers for: * users.updated_at * time_entries.updated_at * time_goals.updated_at - Fixed connection handling to work with plugin's undefined return pattern - Added rich logging throughout initialization process Security: - Database created with proper permissions (644) - Directory permissions set to 755 - No encryption (as per requirements) - Foreign key constraints enabled for data integrity Testing: - Verified table creation - Confirmed schema version tracking - Validated connection registration - Tested WAL mode activation Author: Matthew Raymer --- electron/src/rt/sqlite-init.ts | 483 ++++++++++++++++++++------------- 1 file changed, 299 insertions(+), 184 deletions(-) diff --git a/electron/src/rt/sqlite-init.ts b/electron/src/rt/sqlite-init.ts index 24385903..e2525f2e 100644 --- a/electron/src/rt/sqlite-init.ts +++ b/electron/src/rt/sqlite-init.ts @@ -26,6 +26,9 @@ const logger = { debug: (...args: unknown[]) => console.debug('[SQLite]', ...args), }; +// Add delay utility +const delay = (ms: number): Promise => new Promise(resolve => setTimeout(resolve, ms)); + // Add debug logging utility const debugLog = (stage: string, data?: any) => { const timestamp = new Date().toISOString(); @@ -190,6 +193,179 @@ const getActualPluginInstance = (plugin: any): any => { return instance; }; +// Add debug logging for SQL statements +const logSQLStatement = (index: number, total: number, statement: string) => { + debugLog(`SQL Statement ${index + 1}/${total}:`, { + length: statement.length, + preview: statement.substring(0, 100) + (statement.length > 100 ? '...' : ''), + hasNewlines: statement.includes('\n'), + hasSemicolon: statement.includes(';'), + hasQuotes: statement.includes("'") || statement.includes('"'), + hasParens: statement.includes('(') || statement.includes(')') + }); +}; + +// Split schema into PRAGMA and table creation +const PRAGMA_STATEMENTS = ` +-- Enable foreign keys +PRAGMA foreign_keys = ON; + +-- Enable WAL mode for better concurrency +PRAGMA journal_mode = WAL; + +-- Set synchronous mode for better performance while maintaining safety +PRAGMA synchronous = NORMAL; + +-- Set temp store to memory for better performance +PRAGMA temp_store = MEMORY; + +-- Set page size for better performance +PRAGMA page_size = 4096; + +-- Set cache size to 2000 pages (about 8MB) +PRAGMA cache_size = 2000; +`; + +const TABLE_SCHEMA = ` +-- Create version tracking table +CREATE TABLE IF NOT EXISTS schema_version ( + version INTEGER PRIMARY KEY, + applied_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + description TEXT +); + +-- Create initial schema version record if not exists +INSERT OR IGNORE INTO schema_version (version, description) +VALUES (1, 'Initial schema version'); + +-- Create users table +CREATE TABLE IF NOT EXISTS users ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + username TEXT UNIQUE NOT NULL, + email TEXT UNIQUE NOT NULL, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +-- Create time_entries table +CREATE TABLE IF NOT EXISTS time_entries ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + user_id INTEGER NOT NULL, + description TEXT NOT NULL, + start_time TIMESTAMP NOT NULL, + end_time TIMESTAMP, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE +); + +-- Create time_goals table +CREATE TABLE IF NOT EXISTS time_goals ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + user_id INTEGER NOT NULL, + title TEXT NOT NULL, + description TEXT, + target_hours INTEGER NOT NULL, + start_date TIMESTAMP NOT NULL, + end_date TIMESTAMP, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE +); + +-- Create time_goal_entries table (linking time entries to goals) +CREATE TABLE IF NOT EXISTS time_goal_entries ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + goal_id INTEGER NOT NULL, + entry_id INTEGER NOT NULL, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (goal_id) REFERENCES time_goals(id) ON DELETE CASCADE, + FOREIGN KEY (entry_id) REFERENCES time_entries(id) ON DELETE CASCADE, + UNIQUE(goal_id, entry_id) +); + +-- Create triggers for updated_at (as single statements) +CREATE TRIGGER IF NOT EXISTS update_users_timestamp AFTER UPDATE ON users BEGIN UPDATE users SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; + +CREATE TRIGGER IF NOT EXISTS update_time_entries_timestamp AFTER UPDATE ON time_entries BEGIN UPDATE time_entries SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; + +CREATE TRIGGER IF NOT EXISTS update_time_goals_timestamp AFTER UPDATE ON time_goals BEGIN UPDATE time_goals SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; +`; + +// Improve SQL statement splitting to handle trigger statements +const splitSQLStatements = (sql: string): string[] => { + // First normalize line endings and remove comments + const normalized = sql + .replace(/\r\n/g, '\n') // Normalize line endings + .replace(/--.*$/gm, '') // Remove single line comments + .replace(/\/\*[\s\S]*?\*\//g, '') // Remove multi-line comments + .trim(); + + // Split on semicolons that are not inside quotes, parentheses, or BEGIN/END blocks + const statements: string[] = []; + let currentStatement = ''; + let inString = false; + let stringChar = ''; + let parenDepth = 0; + let inBeginBlock = false; + + for (let i = 0; i < normalized.length; i++) { + const char = normalized[i]; + const nextChar = normalized[i + 1] || ''; + const prevChar = normalized[i - 1] || ''; + + // Handle string literals + if ((char === "'" || char === '"') && prevChar !== '\\') { + if (!inString) { + inString = true; + stringChar = char; + } else if (char === stringChar) { + inString = false; + } + } + + // Handle parentheses + if (!inString) { + if (char === '(') parenDepth++; + if (char === ')') parenDepth--; + } + + // Handle BEGIN/END blocks + if (!inString && char === 'B' && normalized.substring(i, i + 5) === 'BEGIN') { + inBeginBlock = true; + } else if (!inString && char === 'E' && normalized.substring(i, i + 3) === 'END') { + inBeginBlock = false; + } + + // Add character to current statement + currentStatement += char; + + // Check for statement end + if (char === ';' && !inString && parenDepth === 0 && !inBeginBlock) { + const trimmed = currentStatement.trim(); + if (trimmed) { + statements.push(trimmed); + } + currentStatement = ''; + } + } + + // Add any remaining statement + const remaining = currentStatement.trim(); + if (remaining) { + statements.push(remaining); + } + + // Filter out empty statements and normalize + return statements + .map(stmt => stmt.trim()) + .filter(stmt => stmt.length > 0) + .map(stmt => { + // Ensure statement ends with semicolon + return stmt.endsWith(';') ? stmt : stmt + ';'; + }); +}; + export async function initializeSQLite(): Promise { if (sqliteInitializationPromise) { logger.info('SQLite initialization already in progress, waiting...'); @@ -300,215 +476,135 @@ export async function initializeSQLite(): Promise { pathType: typeof sqlitePlugin.fileUtil?.Path?.join }); - // Let plugin handle database naming and suffix + // Simplified connection options const connectionOptions = { - database: 'timesafari', // Base name only + database: 'timesafari', version: 1, readOnly: false, encryption: 'no-encryption', useNative: true, - mode: 'rwc', - location: 'default', // Let plugin handle path resolution - path: fullDbPath // Add explicit path + mode: 'rwc' }; - debugLog('Connection options:', { - ...connectionOptions, - absoluteLocation: dbDir, - fullDbPath, - expectedBehavior: 'Using prototype methods with explicit path' - }); + debugLog('Connection options:', connectionOptions); - // Verify directory state before connection try { - const dirStats = await fs.promises.stat(dbDir); - debugLog('Directory state before connection:', { - exists: true, - isDirectory: dirStats.isDirectory(), - mode: dirStats.mode.toString(8), - uid: dirStats.uid, - gid: dirStats.gid, - size: dirStats.size, - atime: dirStats.atime, - mtime: dirStats.mtime, - ctime: dirStats.ctime + // First create the connection + debugLog('Creating database connection...'); + const createResult = await sqlitePlugin.createConnection(connectionOptions); + debugLog('Create connection result:', { + type: typeof createResult, + isNull: createResult === null, + isUndefined: createResult === undefined, + value: createResult }); - // Check if database file already exists - try { - const dbStats = await fs.promises.stat(fullDbPath); - debugLog('Database file exists:', { - size: dbStats.size, - mode: dbStats.mode.toString(8), - mtime: dbStats.mtime - }); - } catch (error) { - debugLog('Database file does not exist yet (this is expected)'); + // Wait a moment for connection to be registered + debugLog('Waiting for connection registration...'); + await delay(500); + + // Verify connection is registered + const isRegistered = await sqlitePlugin.isDatabase({ + database: connectionOptions.database + }); + + debugLog('Connection registration check:', { + isRegistered, + database: connectionOptions.database + }); + + if (!isRegistered) { + throw new Error('Database not registered after createConnection'); } - } catch (error) { - debugLog('Error checking directory state:', error); - } - // Create connection using prototype methods - debugLog('Calling createConnection...'); - let db; - try { - // Get the prototype methods - const proto = Object.getPrototypeOf(sqlitePlugin); - debugLog('Prototype methods:', { - methods: Object.getOwnPropertyNames(proto), - createConnectionType: typeof proto.createConnection, - openType: typeof proto.open, - createConnectionProto: proto.createConnection?.prototype?.constructor?.name + // Now try to open + debugLog('Attempting to open database...'); + await sqlitePlugin.open({ + database: connectionOptions.database, + version: connectionOptions.version, + readOnly: false, + encryption: connectionOptions.encryption, + useNative: connectionOptions.useNative, + mode: 'rwc' }); - // Try to create connection using prototype method - if (typeof proto.createConnection === 'function') { - debugLog('Using prototype createConnection'); - - // First try to create the connection - const boundCreateConnection = proto.createConnection.bind(sqlitePlugin); - const result = await boundCreateConnection(connectionOptions); - - debugLog('createConnection raw result:', { - type: typeof result, - isNull: result === null, - isUndefined: result === undefined, - value: result + debugLog('Database opened, setting PRAGMAs...'); + + // First set PRAGMAs outside of transaction + const pragmaStatements = splitSQLStatements(PRAGMA_STATEMENTS); + debugLog(`Executing ${pragmaStatements.length} PRAGMA statements`); + + for (const [index, statement] of pragmaStatements.entries()) { + debugLog(`Executing PRAGMA ${index + 1}/${pragmaStatements.length}`); + logSQLStatement(index, pragmaStatements.length, statement); + + await sqlitePlugin.execute({ + database: connectionOptions.database, + statements: statement, + transaction: false }); + } - // Try to open the database directly - debugLog('Attempting to open database directly...'); - try { - const openResult = await sqlitePlugin.open({ - database: connectionOptions.database, - path: fullDbPath, - version: connectionOptions.version, - readOnly: connectionOptions.readOnly, - encryption: connectionOptions.encryption, - useNative: connectionOptions.useNative, - mode: connectionOptions.mode - }); + debugLog('PRAGMAs set, creating tables...'); - debugLog('open result:', { - type: typeof openResult, - isNull: openResult === null, - isUndefined: openResult === undefined, - value: openResult - }); + // Now create tables in a transaction + await sqlitePlugin.beginTransaction({ + database: connectionOptions.database + }); + + try { + // Execute table creation statements in transaction + const tableStatements = splitSQLStatements(TABLE_SCHEMA); + debugLog(`Executing ${tableStatements.length} table creation statements`); - // Try to get the connection after opening - if (sqlitePlugin.getDatabaseConnectionOrThrowError) { - debugLog('Getting connection after open'); - db = await sqlitePlugin.getDatabaseConnectionOrThrowError(connectionOptions.database); - } + for (const [index, statement] of tableStatements.entries()) { + debugLog(`Executing table statement ${index + 1}/${tableStatements.length}`); + logSQLStatement(index, tableStatements.length, statement); - // Verify the database exists - const exists = await sqlitePlugin.isDBExists({ + await sqlitePlugin.execute({ database: connectionOptions.database, - path: fullDbPath + statements: statement, + transaction: false // Already in transaction }); + } - debugLog('Database exists check:', { - exists, - path: fullDbPath, - fileExists: fs.existsSync(fullDbPath) - }); + // Commit transaction + await sqlitePlugin.commitTransaction({ + database: connectionOptions.database + }); + debugLog('Table creation transaction committed'); - // If database doesn't exist, try to create it - if (!exists) { - debugLog('Database does not exist, attempting to create...'); - // Create an empty file to ensure the directory is writable - await fs.promises.writeFile(fullDbPath, ''); - - // Try opening again - await sqlitePlugin.open({ - database: connectionOptions.database, - path: fullDbPath, - version: connectionOptions.version, - readOnly: false, // Force read-write for creation - encryption: connectionOptions.encryption, - useNative: connectionOptions.useNative, - mode: 'rwc' // Force create mode - }); - - // Verify creation - const created = await sqlitePlugin.isDBExists({ - database: connectionOptions.database, - path: fullDbPath - }); - - debugLog('Database creation result:', { - created, - path: fullDbPath, - fileExists: fs.existsSync(fullDbPath), - fileSize: fs.existsSync(fullDbPath) ? fs.statSync(fullDbPath).size : 0 - }); - } - - // Get final connection - if (sqlitePlugin.getDatabaseConnectionOrThrowError) { - debugLog('Getting final connection'); - db = await sqlitePlugin.getDatabaseConnectionOrThrowError(connectionOptions.database); - } - - debugLog('Final connection state:', { - hasConnection: !!db, - type: typeof db, - isNull: db === null, - isUndefined: db === undefined, - keys: db ? Object.keys(db) : null, - methods: db ? Object.getOwnPropertyNames(Object.getPrototypeOf(db)) : null, - prototype: db ? Object.getPrototypeOf(db)?.constructor?.name : null - }); + // Verify tables were created + const tables = await sqlitePlugin.getTableList({ + database: connectionOptions.database + }); + debugLog('Created tables:', tables); - } catch (openError) { - debugLog('Error during open/create:', { - name: openError.name, - message: openError.message, - stack: openError.stack, - code: (openError as any).code, - errno: (openError as any).errno, - syscall: (openError as any).syscall - }); - throw openError; - } - } else { - throw new Error('No valid createConnection method found on prototype'); + // Verify schema version + const versionResult = await sqlitePlugin.query({ + database: connectionOptions.database, + statement: 'SELECT version FROM schema_version;' + }); + debugLog('Schema version:', versionResult); + + } catch (error) { + // Rollback on error + await sqlitePlugin.rollbackTransaction({ + database: connectionOptions.database + }); + debugLog('Table creation failed, transaction rolled back:', error); + throw error; } - } catch (error) { - debugLog('createConnection/open error:', { - name: error.name, - message: error.message, - stack: error.stack, - code: (error as any).code, - errno: (error as any).errno, - syscall: (error as any).syscall - }); - throw error; - } - - if (!db || typeof db !== 'object') { - debugLog('Invalid database connection response:', { - value: db, - type: typeof db, - isNull: db === null, - isUndefined: db === undefined - }); - throw new Error(`Failed to create database connection - invalid response. Path: ${fullDbPath}`); - } - // Verify connection state - debugLog('Verifying connection state...'); - try { - const isOpen = await db.isDBOpen(); - debugLog('Connection state:', { - isOpen, - methods: Object.keys(db), - prototype: Object.getOwnPropertyNames(Object.getPrototypeOf(db)) + // Close the database + await sqlitePlugin.close({ + database: connectionOptions.database }); + debugLog('Database closed after schema creation'); + } catch (error) { - debugLog('Error checking connection state:', error); + debugLog('Error during schema creation:', error); + throw error; } sqliteInitialized = true; @@ -600,13 +696,32 @@ export function setupSQLiteHandlers(): void { expectedBehavior: 'Plugin will append SQLite suffix and handle path resolution' }); + // Create connection (returns undefined but registers internally) const result = await sqlitePlugin.createConnection(connectionOptions); - if (!result || typeof result !== 'object') { - throw new Error('Failed to create database connection - invalid response'); - } + // Wait a moment for connection to be registered + await delay(500); + + // Verify connection is registered + const isRegistered = await sqlitePlugin.isDatabase({ + database: connectionOptions.database + }); - return result; + debugLog('Connection registration check:', { + isRegistered, + database: connectionOptions.database + }); + + if (!isRegistered) { + throw new Error('Database not registered after createConnection'); + } + + // Return success object instead of undefined + return { + success: true, + database: connectionOptions.database, + isRegistered: true + }; } catch (error) { logger.error('Error in sqlite-create-connection:', error); throw error;