From ca6fa71f3839d4fa8bea873590bfa567c3c91dca Mon Sep 17 00:00:00 2001 From: "ethan.chen" Date: Thu, 8 Jan 2026 11:14:35 +0800 Subject: [PATCH] feat: Migrate data storage to PostgreSQL with schema setup, initialization script, and update documentation --- Dockerfile | 3 - README.md | 36 +- docker-compose.yml | 9 +- env.template | 4 + package.json | 4 +- scripts/init-db.ts | 81 ++++ src/index.ts | 31 +- src/storage/database.ts | 559 ++++++++++++++++++--------- src/storage/schema.sql | 81 ++++ src/tools/common/notes.ts | 15 +- src/tools/common/tasks.ts | 17 +- src/tools/family/baby.ts | 6 +- src/tools/family/math.ts | 4 +- src/tools/hobbies/games.ts | 6 +- src/tools/programming/codeSnippet.ts | 15 +- tests/helpers/database-helper.ts | 85 +++- 16 files changed, 718 insertions(+), 238 deletions(-) create mode 100644 scripts/init-db.ts create mode 100644 src/storage/schema.sql diff --git a/Dockerfile b/Dockerfile index 5d236b0..5860266 100644 --- a/Dockerfile +++ b/Dockerfile @@ -28,9 +28,6 @@ RUN bun install --frozen-lockfile --production COPY --from=base /app/dist ./dist COPY --from=base /app/src ./src -# Create data directory for persistent storage -RUN mkdir -p /app/data - # Expose port (if needed for health checks) EXPOSE 3000 diff --git a/README.md b/README.md index 464cf5f..4e33ed9 100644 --- a/README.md +++ b/README.md @@ -176,13 +176,35 @@ Example configuration for Claude Desktop (`claude_desktop_config.json`): ## Data Storage -All data is stored locally in JSON files in the `data/` directory: -- `codeSnippets.json` - Code snippets -- `notes.json` - Personal notes -- `tasks.json` - Tasks -- `babyMilestones.json` - Baby milestones -- `mathResources.json` - Math resources -- `gameWishlist.json` - Game wishlist +All data is stored in PostgreSQL database. The application requires a PostgreSQL database connection. + +### Database Setup + +1. **Configure Database Connection** + + Set the `DATABASE_URL` environment variable in your `.env` file: + ``` + DATABASE_URL=postgresql://user:password@host:port/database + ``` + +2. **Initialize Database Schema** + + Run the initialization script to create all required tables: + ```bash + bun run init-db + ``` + + This will create the following tables: + - `code_snippets` - Code snippets + - `notes` - Personal notes + - `tasks` - Tasks + - `baby_milestones` - Baby milestones + - `math_resources` - Math resources + - `game_wishlist` - Game wishlist + +### Database Schema + +The database schema is defined in `src/storage/schema.sql`. All tables include appropriate indexes for optimal query performance. ## Development diff --git a/docker-compose.yml b/docker-compose.yml index 90d3329..7250028 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -8,16 +8,21 @@ services: container_name: cloud-mcp restart: unless-stopped volumes: - # Mount data directory for persistent storage - - ./data:/app/data # Mount .env file if exists (optional, can use environment variables instead) - ./.env:/app/.env:ro environment: - NODE_ENV=production + # PostgreSQL connection (required) + # - DATABASE_URL=${DATABASE_URL} # Add your environment variables here or use .env file # - NAS_HOST=${NAS_HOST} # - SERVER_HOST=${SERVER_HOST} # etc. + # Note: This service requires an external PostgreSQL database. + # Set DATABASE_URL environment variable to connect to your PostgreSQL instance. + # For local development, you can uncomment the postgres service below: + # depends_on: + # - postgres stdin_open: true tty: true # Health check (optional) diff --git a/env.template b/env.template index b352028..18e218e 100644 --- a/env.template +++ b/env.template @@ -27,6 +27,10 @@ EMAIL_PASSWORD=your-app-password EMAIL_FROM=Your Name EMAIL_SECURE=false +# Database Configuration +# PostgreSQL 数据库连接配置 +DATABASE_URL=postgresql://user:password@host:port/database + # API Keys (optional) # 可选:配置 API 密钥以使用完整功能 # 足球信息 API (football-data.org - 免费注册获取) diff --git a/package.json b/package.json index 499eb2e..2e3c1b0 100644 --- a/package.json +++ b/package.json @@ -13,7 +13,8 @@ "restart:pm2": "pm2 restart cloud-mcp", "test": "bun test", "test:watch": "bun test --watch", - "test:coverage": "bun test --coverage" + "test:coverage": "bun test --coverage", + "init-db": "bun run scripts/init-db.ts" }, "keywords": [ "mcp", @@ -26,6 +27,7 @@ "@modelcontextprotocol/sdk": "^1.0.4", "axios": "^1.7.7", "nodemailer": "^6.9.8", + "postgres": "^3.4.3", "ssh2": "^1.15.0" }, "devDependencies": { diff --git a/scripts/init-db.ts b/scripts/init-db.ts new file mode 100644 index 0000000..8b07344 --- /dev/null +++ b/scripts/init-db.ts @@ -0,0 +1,81 @@ +/** + * Database initialization script + * Creates all required tables in PostgreSQL + */ + +import postgres from "postgres"; +import { readFileSync } from "fs"; +import { join } from "path"; + +async function initDatabase() { + const dbUrl = process.env.DATABASE_URL; + + if (!dbUrl) { + console.error("Error: DATABASE_URL environment variable is required"); + console.error("Please set it in your .env file or export it:"); + console.error(" export DATABASE_URL=postgresql://user:password@host:port/database"); + process.exit(1); + } + + console.log("Connecting to PostgreSQL..."); + const sql = postgres(dbUrl); + + try { + // Test connection + await sql`SELECT 1`; + console.log("✓ Connected to PostgreSQL"); + + // Read schema file + const schemaPath = join(process.cwd(), "src", "storage", "schema.sql"); + console.log(`Reading schema from ${schemaPath}...`); + const schema = readFileSync(schemaPath, "utf-8"); + + // Split by semicolons and execute each statement + const statements = schema + .split(";") + .map((s) => s.trim()) + .filter((s) => s.length > 0 && !s.startsWith("--")); + + console.log(`Executing ${statements.length} SQL statements...`); + + for (const statement of statements) { + if (statement) { + try { + // Use postgres.unsafe() to execute raw SQL + await (sql as any).unsafe(statement); + console.log(`✓ Executed: ${statement.substring(0, 50)}...`); + } catch (error) { + // Check if it's a "already exists" error (which is OK) + const errorMessage = (error as Error).message; + if (errorMessage.includes("already exists") || errorMessage.includes("duplicate")) { + console.log(`⚠ Skipped (already exists): ${statement.substring(0, 50)}...`); + } else { + console.error(`✗ Error executing statement: ${errorMessage}`); + console.error(` Statement: ${statement.substring(0, 100)}...`); + throw error; + } + } + } + } + + console.log("\n✓ Database initialization completed successfully!"); + console.log("\nTables created:"); + console.log(" - code_snippets"); + console.log(" - notes"); + console.log(" - tasks"); + console.log(" - baby_milestones"); + console.log(" - math_resources"); + console.log(" - game_wishlist"); + } catch (error) { + console.error("\n✗ Database initialization failed:", error); + process.exit(1); + } finally { + await sql.end(); + } +} + +// Run initialization +initDatabase().catch((error) => { + console.error("Fatal error:", error); + process.exit(1); +}); diff --git a/src/index.ts b/src/index.ts index 0fd2c9c..22513ae 100644 --- a/src/index.ts +++ b/src/index.ts @@ -5,6 +5,7 @@ import { mcpServer } from "./server.js"; import { logger } from "./utils/logger.js"; +import { database } from "./storage/database.js"; // Register all tools import { registerCodeSnippetTools } from "./tools/programming/codeSnippet.js"; @@ -57,10 +58,30 @@ registerNoteTools(); registerTaskTools(); registerEmailTools(); -logger.info("All tools registered. Starting MCP server..."); +logger.info("All tools registered. Initializing database..."); -// Start the server -mcpServer.start().catch((error) => { - logger.error("Failed to start MCP server:", error); - process.exit(1); +// Initialize database connection +database + .initialize() + .then(() => { + logger.info("Database connected successfully. Starting MCP server..."); + // Start the server + return mcpServer.start(); + }) + .catch((error) => { + logger.error("Failed to initialize database or start MCP server:", error); + process.exit(1); + }); + +// Graceful shutdown +process.on("SIGINT", async () => { + logger.info("Shutting down..."); + await database.close(); + process.exit(0); +}); + +process.on("SIGTERM", async () => { + logger.info("Shutting down..."); + await database.close(); + process.exit(0); }); diff --git a/src/storage/database.ts b/src/storage/database.ts index 09f4bba..df5793a 100644 --- a/src/storage/database.ts +++ b/src/storage/database.ts @@ -1,21 +1,11 @@ /** * Database/storage layer for the MCP server - * Uses JSON file storage for simplicity + * Uses PostgreSQL for data persistence */ -import { existsSync, mkdirSync, readFileSync, writeFileSync } from "fs"; -import { join } from "path"; - -// Use environment variable for test data directory, or default to project data directory -const getDataDir = () => { - if (process.env.MCP_TEST_DATA_DIR) { - return process.env.MCP_TEST_DATA_DIR; - } - return join(process.cwd(), "data"); -}; - -const DATA_DIR = getDataDir(); +import postgres from "postgres"; +// Export interfaces (keep them unchanged for compatibility) export interface CodeSnippet { id: string; title: string; @@ -72,222 +62,433 @@ export interface GameWishlist { } class Database { - private getDataDir(): string { - return getDataDir(); - } + private sql: postgres.Sql | null = null; - private ensureDataDir(): void { - const dataDir = this.getDataDir(); - if (!existsSync(dataDir)) { - mkdirSync(dataDir, { recursive: true }); + private getConnectionString(): string { + // For tests, use test database URL if provided + const testUrl = process.env.MCP_TEST_DATABASE_URL; + if (testUrl) { + return testUrl; } - } - - private getFilePath(collection: string): string { - this.ensureDataDir(); - return join(this.getDataDir(), `${collection}.json`); - } - - private readCollection(collection: string): T[] { - const filePath = this.getFilePath(collection); - if (!existsSync(filePath)) { - return []; + + const dbUrl = process.env.DATABASE_URL; + if (!dbUrl) { + throw new Error( + "DATABASE_URL environment variable is required. Please set it in your .env file." + ); } + return dbUrl; + } + + private getSql(): postgres.Sql { + if (!this.sql) { + const connectionString = this.getConnectionString(); + this.sql = postgres(connectionString, { + max: 10, // Connection pool size + idle_timeout: 20, + connect_timeout: 10, + }); + } + return this.sql; + } + + async initialize(): Promise { + // Test connection try { - const content = readFileSync(filePath, "utf-8"); - return JSON.parse(content); + await this.getSql()`SELECT 1`; } catch (error) { - console.error(`Error reading ${collection}:`, error); - return []; + console.error("Failed to connect to PostgreSQL:", error); + throw new Error( + `Database connection failed: ${error instanceof Error ? error.message : String(error)}` + ); } } - private writeCollection(collection: string, data: T[]): void { - const filePath = this.getFilePath(collection); - try { - writeFileSync(filePath, JSON.stringify(data, null, 2), "utf-8"); - } catch (error) { - console.error(`Error writing ${collection}:`, error); - throw error; + async close(): Promise { + if (this.sql) { + await this.sql.end(); + this.sql = null; } } // Code Snippets - saveCodeSnippet(snippet: CodeSnippet): void { - const snippets = this.readCollection("codeSnippets"); - const index = snippets.findIndex((s) => s.id === snippet.id); - if (index >= 0) { - snippets[index] = { ...snippet, updatedAt: new Date().toISOString() }; + async saveCodeSnippet(snippet: CodeSnippet): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO code_snippets (id, title, code, language, tags, category, created_at, updated_at) + VALUES (${snippet.id}, ${snippet.title}, ${snippet.code}, ${snippet.language}, ${snippet.tags}, ${snippet.category}, ${snippet.createdAt}, ${snippet.updatedAt}) + ON CONFLICT (id) DO UPDATE SET + title = EXCLUDED.title, + code = EXCLUDED.code, + language = EXCLUDED.language, + tags = EXCLUDED.tags, + category = EXCLUDED.category, + updated_at = EXCLUDED.updated_at + `; + } + + async getCodeSnippets(): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, code, language, tags, category, created_at, updated_at + FROM code_snippets + ORDER BY updated_at DESC + `; + return rows.map((row) => ({ + id: row.id, + title: row.title, + code: row.code, + language: row.language, + tags: row.tags || [], + category: row.category || undefined, + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + })); + } + + async getCodeSnippet(id: string): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, code, language, tags, category, created_at, updated_at + FROM code_snippets + WHERE id = ${id} + LIMIT 1 + `; + if (rows.length === 0) { + return undefined; + } + const row = rows[0]; + return { + id: row.id, + title: row.title, + code: row.code, + language: row.language, + tags: row.tags || [], + category: row.category || undefined, + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + }; + } + + async deleteCodeSnippet(id: string): Promise { + const sql = this.getSql(); + const result = await sql`DELETE FROM code_snippets WHERE id = ${id}`; + return result.count > 0; + } + + async searchCodeSnippets(query: string, tags?: string[]): Promise { + const sql = this.getSql(); + const searchPattern = `%${query}%`; + let rows; + + if (tags && tags.length > 0) { + rows = await sql` + SELECT id, title, code, language, tags, category, created_at, updated_at + FROM code_snippets + WHERE ( + title ILIKE ${searchPattern} OR + code ILIKE ${searchPattern} OR + language ILIKE ${searchPattern} + ) AND tags && ${tags} + ORDER BY updated_at DESC + `; } else { - snippets.push(snippet); + rows = await sql` + SELECT id, title, code, language, tags, category, created_at, updated_at + FROM code_snippets + WHERE title ILIKE ${searchPattern} OR code ILIKE ${searchPattern} OR language ILIKE ${searchPattern} + ORDER BY updated_at DESC + `; } - this.writeCollection("codeSnippets", snippets); - } - getCodeSnippets(): CodeSnippet[] { - return this.readCollection("codeSnippets"); - } - - getCodeSnippet(id: string): CodeSnippet | undefined { - const snippets = this.readCollection("codeSnippets"); - return snippets.find((s) => s.id === id); - } - - deleteCodeSnippet(id: string): boolean { - const snippets = this.readCollection("codeSnippets"); - const filtered = snippets.filter((s) => s.id !== id); - if (filtered.length < snippets.length) { - this.writeCollection("codeSnippets", filtered); - return true; - } - return false; - } - - searchCodeSnippets(query: string, tags?: string[]): CodeSnippet[] { - const snippets = this.readCollection("codeSnippets"); - const lowerQuery = query.toLowerCase(); - return snippets.filter((s) => { - const matchesQuery = - s.title.toLowerCase().includes(lowerQuery) || - s.code.toLowerCase().includes(lowerQuery) || - s.language.toLowerCase().includes(lowerQuery); - const matchesTags = - !tags || tags.length === 0 || tags.some((tag) => s.tags.includes(tag)); - return matchesQuery && matchesTags; - }); + return rows.map((row) => ({ + id: row.id, + title: row.title, + code: row.code, + language: row.language, + tags: row.tags || [], + category: row.category || undefined, + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + })); } // Notes - saveNote(note: Note): void { - const notes = this.readCollection("notes"); - const index = notes.findIndex((n) => n.id === note.id); - if (index >= 0) { - notes[index] = { ...note, updatedAt: new Date().toISOString() }; - } else { - notes.push(note); + async saveNote(note: Note): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO notes (id, title, content, tags, created_at, updated_at) + VALUES (${note.id}, ${note.title}, ${note.content}, ${note.tags}, ${note.createdAt}, ${note.updatedAt}) + ON CONFLICT (id) DO UPDATE SET + title = EXCLUDED.title, + content = EXCLUDED.content, + tags = EXCLUDED.tags, + updated_at = EXCLUDED.updated_at + `; + } + + async getNotes(): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, content, tags, created_at, updated_at + FROM notes + ORDER BY updated_at DESC + `; + return rows.map((row) => ({ + id: row.id, + title: row.title, + content: row.content, + tags: row.tags || [], + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + })); + } + + async getNote(id: string): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, content, tags, created_at, updated_at + FROM notes + WHERE id = ${id} + LIMIT 1 + `; + if (rows.length === 0) { + return undefined; } - this.writeCollection("notes", notes); + const row = rows[0]; + return { + id: row.id, + title: row.title, + content: row.content, + tags: row.tags || [], + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + }; } - getNotes(): Note[] { - return this.readCollection("notes"); + async searchNotes(query: string): Promise { + const sql = this.getSql(); + const searchPattern = `%${query}%`; + const rows = await sql` + SELECT id, title, content, tags, created_at, updated_at + FROM notes + WHERE title ILIKE ${searchPattern} OR content ILIKE ${searchPattern} OR EXISTS ( + SELECT 1 FROM unnest(tags) AS tag WHERE tag ILIKE ${searchPattern} + ) + ORDER BY updated_at DESC + `; + return rows.map((row) => ({ + id: row.id, + title: row.title, + content: row.content, + tags: row.tags || [], + createdAt: row.created_at.toISOString(), + updatedAt: row.updated_at.toISOString(), + })); } - getNote(id: string): Note | undefined { - const notes = this.readCollection("notes"); - return notes.find((n) => n.id === id); - } - - searchNotes(query: string): Note[] { - const notes = this.readCollection("notes"); - const lowerQuery = query.toLowerCase(); - return notes.filter( - (n) => - n.title.toLowerCase().includes(lowerQuery) || - n.content.toLowerCase().includes(lowerQuery) || - n.tags.some((tag) => tag.toLowerCase().includes(lowerQuery)) - ); - } - - deleteNote(id: string): boolean { - const notes = this.readCollection("notes"); - const filtered = notes.filter((n) => n.id !== id); - if (filtered.length < notes.length) { - this.writeCollection("notes", filtered); - return true; - } - return false; + async deleteNote(id: string): Promise { + const sql = this.getSql(); + const result = await sql`DELETE FROM notes WHERE id = ${id}`; + return result.count > 0; } // Tasks - saveTask(task: Task): void { - const tasks = this.readCollection("tasks"); - const index = tasks.findIndex((t) => t.id === task.id); - if (index >= 0) { - tasks[index] = task; - } else { - tasks.push(task); - } - this.writeCollection("tasks", tasks); + async saveTask(task: Task): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO tasks (id, title, description, completed, created_at, completed_at) + VALUES (${task.id}, ${task.title}, ${task.description}, ${task.completed}, ${task.createdAt}, ${task.completedAt || null}) + ON CONFLICT (id) DO UPDATE SET + title = EXCLUDED.title, + description = EXCLUDED.description, + completed = EXCLUDED.completed, + completed_at = EXCLUDED.completed_at + `; } - getTasks(completed?: boolean): Task[] { - const tasks = this.readCollection("tasks"); + async getTasks(completed?: boolean): Promise { + const sql = this.getSql(); + let rows; if (completed === undefined) { - return tasks; + rows = await sql` + SELECT id, title, description, completed, created_at, completed_at + FROM tasks + ORDER BY created_at DESC + `; + } else { + rows = await sql` + SELECT id, title, description, completed, created_at, completed_at + FROM tasks + WHERE completed = ${completed} + ORDER BY created_at DESC + `; } - return tasks.filter((t) => t.completed === completed); + return rows.map((row) => ({ + id: row.id, + title: row.title, + description: row.description || undefined, + completed: row.completed, + createdAt: row.created_at.toISOString(), + completedAt: row.completed_at ? row.completed_at.toISOString() : undefined, + })); } - getTask(id: string): Task | undefined { - const tasks = this.readCollection("tasks"); - return tasks.find((t) => t.id === id); + async getTask(id: string): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, description, completed, created_at, completed_at + FROM tasks + WHERE id = ${id} + LIMIT 1 + `; + if (rows.length === 0) { + return undefined; + } + const row = rows[0]; + return { + id: row.id, + title: row.title, + description: row.description || undefined, + completed: row.completed, + createdAt: row.created_at.toISOString(), + completedAt: row.completed_at ? row.completed_at.toISOString() : undefined, + }; } // Baby Milestones - saveBabyMilestone(milestone: BabyMilestone): void { - const milestones = this.readCollection("babyMilestones"); - milestones.push(milestone); - this.writeCollection("babyMilestones", milestones); + async saveBabyMilestone(milestone: BabyMilestone): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO baby_milestones (id, title, description, date, created_at) + VALUES (${milestone.id}, ${milestone.title}, ${milestone.description}, ${milestone.date}, ${milestone.createdAt}) + `; } - getBabyMilestones(): BabyMilestone[] { - return this.readCollection("babyMilestones"); + async getBabyMilestones(): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, description, date, created_at + FROM baby_milestones + ORDER BY date DESC + `; + return rows.map((row) => ({ + id: row.id, + title: row.title, + description: row.description, + date: row.date instanceof Date + ? row.date.toISOString().split("T")[0] + : String(row.date).split("T")[0], // Format as YYYY-MM-DD + createdAt: row.created_at instanceof Date + ? row.created_at.toISOString() + : String(row.created_at), + })); } // Math Resources - saveMathResource(resource: MathResource): void { - const resources = this.readCollection("mathResources"); - const index = resources.findIndex((r) => r.id === resource.id); - if (index >= 0) { - resources[index] = resource; + async saveMathResource(resource: MathResource): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO math_resources (id, title, content, grade, difficulty, tags, created_at) + VALUES (${resource.id}, ${resource.title}, ${resource.content}, ${resource.grade || null}, ${resource.difficulty || null}, ${resource.tags}, ${resource.createdAt}) + ON CONFLICT (id) DO UPDATE SET + title = EXCLUDED.title, + content = EXCLUDED.content, + grade = EXCLUDED.grade, + difficulty = EXCLUDED.difficulty, + tags = EXCLUDED.tags + `; + } + + async getMathResources(): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, title, content, grade, difficulty, tags, created_at + FROM math_resources + ORDER BY created_at DESC + `; + return rows.map((row) => ({ + id: row.id, + title: row.title, + content: row.content, + grade: row.grade || undefined, + difficulty: row.difficulty || undefined, + tags: row.tags || [], + createdAt: row.created_at.toISOString(), + })); + } + + async searchMathResources(query: string, grade?: string): Promise { + const sql = this.getSql(); + const searchPattern = `%${query}%`; + let rows; + + if (grade) { + rows = await sql` + SELECT id, title, content, grade, difficulty, tags, created_at + FROM math_resources + WHERE ( + title ILIKE ${searchPattern} OR + content ILIKE ${searchPattern} OR + EXISTS (SELECT 1 FROM unnest(tags) AS tag WHERE tag ILIKE ${searchPattern}) + ) AND grade = ${grade} + ORDER BY created_at DESC + `; } else { - resources.push(resource); + rows = await sql` + SELECT id, title, content, grade, difficulty, tags, created_at + FROM math_resources + WHERE title ILIKE ${searchPattern} OR content ILIKE ${searchPattern} OR EXISTS ( + SELECT 1 FROM unnest(tags) AS tag WHERE tag ILIKE ${searchPattern} + ) + ORDER BY created_at DESC + `; } - this.writeCollection("mathResources", resources); - } - getMathResources(): MathResource[] { - return this.readCollection("mathResources"); - } - - searchMathResources(query: string, grade?: string): MathResource[] { - const resources = this.readCollection("mathResources"); - const lowerQuery = query.toLowerCase(); - return resources.filter((r) => { - const matchesQuery = - r.title.toLowerCase().includes(lowerQuery) || - r.content.toLowerCase().includes(lowerQuery) || - r.tags.some((tag) => tag.toLowerCase().includes(lowerQuery)); - const matchesGrade = !grade || r.grade === grade; - return matchesQuery && matchesGrade; - }); + return rows.map((row) => ({ + id: row.id, + title: row.title, + content: row.content, + grade: row.grade || undefined, + difficulty: row.difficulty || undefined, + tags: row.tags || [], + createdAt: row.created_at.toISOString(), + })); } // Game Wishlist - saveGameWishlist(game: GameWishlist): void { - const games = this.readCollection("gameWishlist"); - const index = games.findIndex((g) => g.id === game.id); - if (index >= 0) { - games[index] = game; - } else { - games.push(game); - } - this.writeCollection("gameWishlist", games); + async saveGameWishlist(game: GameWishlist): Promise { + const sql = this.getSql(); + await sql` + INSERT INTO game_wishlist (id, game_name, platform, notes, added_at) + VALUES (${game.id}, ${game.gameName}, ${game.platform || null}, ${game.notes || null}, ${game.addedAt}) + ON CONFLICT (id) DO UPDATE SET + game_name = EXCLUDED.game_name, + platform = EXCLUDED.platform, + notes = EXCLUDED.notes + `; } - getGameWishlist(): GameWishlist[] { - return this.readCollection("gameWishlist"); + async getGameWishlist(): Promise { + const sql = this.getSql(); + const rows = await sql` + SELECT id, game_name, platform, notes, added_at + FROM game_wishlist + ORDER BY added_at DESC + `; + return rows.map((row) => ({ + id: row.id, + gameName: row.game_name, + platform: row.platform || undefined, + notes: row.notes || undefined, + addedAt: row.added_at.toISOString(), + })); } - deleteGameWishlist(id: string): boolean { - const games = this.readCollection("gameWishlist"); - const filtered = games.filter((g) => g.id !== id); - if (filtered.length < games.length) { - this.writeCollection("gameWishlist", filtered); - return true; - } - return false; + async deleteGameWishlist(id: string): Promise { + const sql = this.getSql(); + const result = await sql`DELETE FROM game_wishlist WHERE id = ${id}`; + return result.count > 0; } } diff --git a/src/storage/schema.sql b/src/storage/schema.sql new file mode 100644 index 0000000..5765ad5 --- /dev/null +++ b/src/storage/schema.sql @@ -0,0 +1,81 @@ +-- Database schema for Cloud MCP Server +-- PostgreSQL database schema + +-- Code Snippets table +CREATE TABLE IF NOT EXISTS code_snippets ( + id VARCHAR(255) PRIMARY KEY, + title TEXT NOT NULL, + code TEXT NOT NULL, + language VARCHAR(100) NOT NULL, + tags TEXT[] DEFAULT '{}', + category VARCHAR(100), + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() +); + +-- Notes table +CREATE TABLE IF NOT EXISTS notes ( + id VARCHAR(255) PRIMARY KEY, + title TEXT NOT NULL, + content TEXT NOT NULL, + tags TEXT[] DEFAULT '{}', + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() +); + +-- Tasks table +CREATE TABLE IF NOT EXISTS tasks ( + id VARCHAR(255) PRIMARY KEY, + title TEXT NOT NULL, + description TEXT, + completed BOOLEAN NOT NULL DEFAULT FALSE, + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), + completed_at TIMESTAMP WITH TIME ZONE +); + +-- Baby Milestones table +CREATE TABLE IF NOT EXISTS baby_milestones ( + id VARCHAR(255) PRIMARY KEY, + title TEXT NOT NULL, + description TEXT NOT NULL, + date DATE NOT NULL, + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() +); + +-- Math Resources table +CREATE TABLE IF NOT EXISTS math_resources ( + id VARCHAR(255) PRIMARY KEY, + title TEXT NOT NULL, + content TEXT NOT NULL, + grade VARCHAR(50), + difficulty VARCHAR(50), + tags TEXT[] DEFAULT '{}', + created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() +); + +-- Game Wishlist table +CREATE TABLE IF NOT EXISTS game_wishlist ( + id VARCHAR(255) PRIMARY KEY, + game_name TEXT NOT NULL, + platform VARCHAR(100), + notes TEXT, + added_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() +); + +-- Create indexes for better search performance +CREATE INDEX IF NOT EXISTS idx_code_snippets_tags ON code_snippets USING GIN(tags); +CREATE INDEX IF NOT EXISTS idx_code_snippets_language ON code_snippets(language); +CREATE INDEX IF NOT EXISTS idx_code_snippets_category ON code_snippets(category); + +CREATE INDEX IF NOT EXISTS idx_notes_tags ON notes USING GIN(tags); + +CREATE INDEX IF NOT EXISTS idx_tasks_completed ON tasks(completed); +CREATE INDEX IF NOT EXISTS idx_tasks_created_at ON tasks(created_at); + +CREATE INDEX IF NOT EXISTS idx_baby_milestones_date ON baby_milestones(date); + +CREATE INDEX IF NOT EXISTS idx_math_resources_tags ON math_resources USING GIN(tags); +CREATE INDEX IF NOT EXISTS idx_math_resources_grade ON math_resources(grade); +CREATE INDEX IF NOT EXISTS idx_math_resources_difficulty ON math_resources(difficulty); + +CREATE INDEX IF NOT EXISTS idx_game_wishlist_platform ON game_wishlist(platform); diff --git a/src/tools/common/notes.ts b/src/tools/common/notes.ts index 532bb3e..5038581 100644 --- a/src/tools/common/notes.ts +++ b/src/tools/common/notes.ts @@ -39,18 +39,19 @@ export function registerNoteTools(): void { }, async (args) => { const now = new Date().toISOString(); + const existingNote = args.id + ? await database.getNote(args.id as string) + : undefined; const note: Note = { id: (args.id as string) || randomUUID(), title: args.title as string, content: args.content as string, tags: (args.tags as string[]) || [], - createdAt: args.id - ? database.getNote(args.id)?.createdAt || now - : now, + createdAt: existingNote?.createdAt || now, updatedAt: now, }; - database.saveNote(note); + await database.saveNote(note); return { content: [ @@ -81,7 +82,7 @@ export function registerNoteTools(): void { }, async (args) => { const query = args.query as string; - const notes = database.searchNotes(query); + const notes = await database.searchNotes(query); if (notes.length === 0) { return { @@ -128,7 +129,7 @@ export function registerNoteTools(): void { }, }, async (args) => { - const notes = database.getNotes(); + const notes = await database.getNotes(); const limit = args.limit as number | undefined; // Sort by updated date (newest first) @@ -185,7 +186,7 @@ export function registerNoteTools(): void { }, async (args) => { const id = args.id as string; - const deleted = database.deleteNote(id); + const deleted = await database.deleteNote(id); if (deleted) { return { diff --git a/src/tools/common/tasks.ts b/src/tools/common/tasks.ts index 0cc96a4..eac19b4 100644 --- a/src/tools/common/tasks.ts +++ b/src/tools/common/tasks.ts @@ -37,7 +37,7 @@ export function registerTaskTools(): void { createdAt: new Date().toISOString(), }; - database.saveTask(task); + await database.saveTask(task); return { content: [ @@ -67,7 +67,7 @@ export function registerTaskTools(): void { }, async (args) => { const completed = args.completed as boolean | undefined; - const tasks = database.getTasks(completed); + const tasks = await database.getTasks(completed); if (tasks.length === 0) { const statusText = completed === true ? 'completed' : completed === false ? 'pending' : ''; @@ -93,9 +93,12 @@ export function registerTaskTools(): void { }) .join('\n\n---\n\n'); - const total = database.getTasks().length; - const completedCount = database.getTasks(true).length; - const pendingCount = database.getTasks(false).length; + const allTasks = await database.getTasks(); + const completedTasks = await database.getTasks(true); + const pendingTasks = await database.getTasks(false); + const total = allTasks.length; + const completedCount = completedTasks.length; + const pendingCount = pendingTasks.length; return { content: [ @@ -126,7 +129,7 @@ export function registerTaskTools(): void { }, async (args) => { const id = args.id as string; - const task = database.getTask(id); + const task = await database.getTask(id); if (!task) { return { @@ -152,7 +155,7 @@ export function registerTaskTools(): void { task.completed = true; task.completedAt = new Date().toISOString(); - database.saveTask(task); + await database.saveTask(task); return { content: [ diff --git a/src/tools/family/baby.ts b/src/tools/family/baby.ts index 3a9a6e5..8f2cc60 100644 --- a/src/tools/family/baby.ts +++ b/src/tools/family/baby.ts @@ -42,7 +42,7 @@ export function registerBabyTools(): void { createdAt: now, }; - database.saveBabyMilestone(milestone); + await database.saveBabyMilestone(milestone); return { content: [ @@ -71,7 +71,7 @@ export function registerBabyTools(): void { }, }, async (args) => { - const milestones = database.getBabyMilestones(); + const milestones = await database.getBabyMilestones(); const limit = args.limit as number | undefined; // Sort by date (newest first) @@ -157,7 +157,7 @@ export function registerBabyTools(): void { createdAt: new Date().toISOString(), }; - db.saveTask(task); + await db.saveTask(task); // Common baby reminders reference const commonReminders: Record = { diff --git a/src/tools/family/math.ts b/src/tools/family/math.ts index 8b995e4..ce8ecb8 100644 --- a/src/tools/family/math.ts +++ b/src/tools/family/math.ts @@ -32,7 +32,7 @@ export function registerMathTools(): void { const query = args.query as string; const grade = args.grade as string | undefined; - const resources = database.searchMathResources(query, grade); + const resources = await database.searchMathResources(query, grade); if (resources.length === 0) { return { @@ -218,7 +218,7 @@ export function registerMathTools(): void { createdAt: now, }; - database.saveMathResource(resource); + await database.saveMathResource(resource); return { content: [ diff --git a/src/tools/hobbies/games.ts b/src/tools/hobbies/games.ts index 076a01c..d699164 100644 --- a/src/tools/hobbies/games.ts +++ b/src/tools/hobbies/games.ts @@ -224,7 +224,7 @@ export function registerGameTools(): void { addedAt: new Date().toISOString(), }; - database.saveGameWishlist(game); + await database.saveGameWishlist(game); return { content: [ @@ -235,7 +235,7 @@ export function registerGameTools(): void { ], }; } else if (action === 'list') { - const games = database.getGameWishlist(); + const games = await database.getGameWishlist(); if (games.length === 0) { return { @@ -277,7 +277,7 @@ export function registerGameTools(): void { }; } - const deleted = database.deleteGameWishlist(id); + const deleted = await database.deleteGameWishlist(id); if (deleted) { return { diff --git a/src/tools/programming/codeSnippet.ts b/src/tools/programming/codeSnippet.ts index 7bacbf8..8c3a214 100644 --- a/src/tools/programming/codeSnippet.ts +++ b/src/tools/programming/codeSnippet.ts @@ -48,6 +48,9 @@ export function registerCodeSnippetTools(): void { }, async (args) => { const now = new Date().toISOString(); + const existingSnippet = args.id + ? await database.getCodeSnippet(args.id as string) + : undefined; const snippet: CodeSnippet = { id: (args.id as string) || randomUUID(), title: args.title as string, @@ -55,13 +58,11 @@ export function registerCodeSnippetTools(): void { language: args.language as string, tags: args.tags as string[], category: args.category as string, - createdAt: args.id - ? database.getCodeSnippet(args.id as string)?.createdAt || now - : now, + createdAt: existingSnippet?.createdAt || now, updatedAt: now, }; - database.saveCodeSnippet(snippet); + await database.saveCodeSnippet(snippet); return { content: [ @@ -98,7 +99,7 @@ export function registerCodeSnippetTools(): void { async (args) => { const query = args.query as string; const tags = args.tags as string[] | undefined; - const snippets = database.searchCodeSnippets(query, tags); + const snippets = await database.searchCodeSnippets(query, tags); if (snippets.length === 0) { return { @@ -149,7 +150,7 @@ export function registerCodeSnippetTools(): void { }, }, async (args) => { - const snippets = database.getCodeSnippets(); + const snippets = await database.getCodeSnippets(); const limit = args.limit as number | undefined; const limited = limit ? snippets.slice(0, limit) : snippets; @@ -202,7 +203,7 @@ export function registerCodeSnippetTools(): void { }, async (args) => { const id = args.id as string; - const deleted = database.deleteCodeSnippet(id); + const deleted = await database.deleteCodeSnippet(id); if (deleted) { return { diff --git a/tests/helpers/database-helper.ts b/tests/helpers/database-helper.ts index b057188..2cef9ad 100644 --- a/tests/helpers/database-helper.ts +++ b/tests/helpers/database-helper.ts @@ -3,27 +3,88 @@ */ import { database } from "../../src/storage/database.js"; +import { readFileSync } from "fs"; import { join } from "path"; -import { mkdirSync } from "fs"; import type { TestContext } from "./test-utils.js"; /** - * Setup test database with isolated data directory + * Setup test database with isolated database connection + * Uses MCP_TEST_DATABASE_URL if provided, otherwise uses DATABASE_URL with a test suffix */ -export function setupTestDatabase(testContext: TestContext): () => void { - const testDataDir = join(testContext.tempDir, "data"); - mkdirSync(testDataDir, { recursive: true }); +export async function setupTestDatabase(testContext: TestContext): Promise<() => Promise> { + // Use test database URL if provided, otherwise use main database URL + const testDbUrl = process.env.MCP_TEST_DATABASE_URL || process.env.DATABASE_URL; + + if (!testDbUrl) { + throw new Error( + "MCP_TEST_DATABASE_URL or DATABASE_URL environment variable is required for tests" + ); + } - // Set environment variable for test data directory - const originalDataDir = process.env.MCP_TEST_DATA_DIR; - process.env.MCP_TEST_DATA_DIR = testDataDir; + // Set test database URL + const originalDbUrl = process.env.DATABASE_URL; + process.env.DATABASE_URL = testDbUrl; + + // Initialize database connection + await database.initialize(); + + // Create tables if they don't exist (using schema.sql) + try { + const schemaPath = join(process.cwd(), "src", "storage", "schema.sql"); + const schema = readFileSync(schemaPath, "utf-8"); + + // Execute schema (split by semicolons and execute each statement) + const statements = schema + .split(";") + .map((s) => s.trim()) + .filter((s) => s.length > 0 && !s.startsWith("--")); + + // We'll use the database connection directly + // Note: This is a simplified approach. In production, you might want to use a migration tool + const sql = (database as any).getSql(); + for (const statement of statements) { + if (statement) { + try { + // Use postgres.unsafe() to execute raw SQL + await (sql as any).unsafe(statement); + } catch (error) { + // Ignore errors for IF NOT EXISTS statements + const errorMsg = (error as Error).message; + if (!errorMsg.includes("already exists") && !errorMsg.includes("duplicate")) { + console.warn(`Schema statement warning: ${errorMsg}`); + } + } + } + } + } catch (error) { + console.warn("Could not execute schema.sql:", error); + // Continue anyway - tables might already exist + } + + // Clean up all tables before each test + await cleanupTestData(); // Return cleanup function - return () => { - if (originalDataDir) { - process.env.MCP_TEST_DATA_DIR = originalDataDir; + return async () => { + await cleanupTestData(); + await database.close(); + if (originalDbUrl) { + process.env.DATABASE_URL = originalDbUrl; } else { - delete process.env.MCP_TEST_DATA_DIR; + delete process.env.DATABASE_URL; } }; } + +/** + * Clean up test data from all tables + */ +async function cleanupTestData(): Promise { + try { + const sql = (database as any).getSql(); + await sql`TRUNCATE TABLE code_snippets, notes, tasks, baby_milestones, math_resources, game_wishlist RESTART IDENTITY CASCADE`; + } catch (error) { + // Tables might not exist yet, ignore + console.warn("Could not truncate test tables:", error); + } +}