- 新增部署脚本 `build-deploy-bundle.mjs`,用于构建和部署 web 和 server 目录。 - 新增样式文件 `index-acd65452.css`,包含基础样式和响应式设计。 - 新增脚本 `repro-import-text.mjs`,用于测试文本导入 API。 - 新增测试文件 `db-migration-score-zero.test.ts`,验证历史数据库中 questions.score 约束的迁移逻辑。 - 更新数据库初始化逻辑,允许插入 score=0 的问题。
338 lines
10 KiB
TypeScript
338 lines
10 KiB
TypeScript
import path from 'path';
|
||
import fs from 'fs';
|
||
import { v4 as uuidv4 } from 'uuid';
|
||
import { createRequire } from 'module';
|
||
import { fileURLToPath } from 'url';
|
||
|
||
// 在ES模块中创建require函数,用于兼容CommonJS模块
|
||
const require = createRequire(import.meta.url);
|
||
|
||
const DEFAULT_DB_DIR = path.join(process.cwd(), 'data');
|
||
const DEFAULT_DB_PATH = path.join(DEFAULT_DB_DIR, 'survey.db');
|
||
|
||
const DB_PATH = process.env.DB_PATH || DEFAULT_DB_PATH;
|
||
const DB_DIR = path.dirname(DB_PATH);
|
||
|
||
// 确保数据目录存在
|
||
if (!fs.existsSync(DB_DIR)) {
|
||
fs.mkdirSync(DB_DIR, { recursive: true });
|
||
}
|
||
|
||
// 延迟初始化数据库连接
|
||
let db: any = null;
|
||
let isInitialized = false;
|
||
|
||
// 初始化数据库连接的函数
|
||
export const initDbConnection = async () => {
|
||
if (!isInitialized) {
|
||
try {
|
||
// 使用require加载sqlite3,因为它是CommonJS模块
|
||
const sqlite3 = require('sqlite3');
|
||
db = new sqlite3.Database(DB_PATH, (err: Error) => {
|
||
if (err) {
|
||
console.error('数据库连接失败:', err);
|
||
} else {
|
||
console.log('数据库连接成功');
|
||
// 启用外键约束
|
||
db.run('PRAGMA foreign_keys = ON');
|
||
}
|
||
});
|
||
isInitialized = true;
|
||
} catch (error) {
|
||
console.error('初始化数据库失败:', error);
|
||
// 初始化失败,不设置isInitialized为true,允许后续调用再次尝试
|
||
return null;
|
||
}
|
||
}
|
||
return db;
|
||
};
|
||
|
||
// 导出一个函数,用于获取数据库连接
|
||
export const getDb = async () => {
|
||
if (!db) {
|
||
return await initDbConnection();
|
||
}
|
||
return db;
|
||
};
|
||
|
||
const exec = async (sql: string): Promise<void> => {
|
||
return new Promise(async (resolve, reject) => {
|
||
const db = await getDb();
|
||
if (!db) {
|
||
reject(new Error('数据库连接未初始化'));
|
||
return;
|
||
}
|
||
db.exec(sql, (err: Error) => {
|
||
if (err) reject(err);
|
||
else resolve();
|
||
});
|
||
});
|
||
};
|
||
|
||
const tableExists = async (tableName: string): Promise<boolean> => {
|
||
const row = await get(
|
||
"SELECT name FROM sqlite_master WHERE type='table' AND name=?",
|
||
[tableName]
|
||
);
|
||
return Boolean(row);
|
||
};
|
||
|
||
const columnExists = async (tableName: string, columnName: string): Promise<boolean> => {
|
||
const columns = await query(`PRAGMA table_info(${tableName})`);
|
||
return columns.some((col: any) => col.name === columnName);
|
||
};
|
||
|
||
const ensureColumn = async (tableName: string, columnDefSql: string, columnName: string) => {
|
||
if (!(await columnExists(tableName, columnName))) {
|
||
console.log(`添加列 ${tableName}.${columnName}`);
|
||
await exec(`ALTER TABLE ${tableName} ADD COLUMN ${columnDefSql}`);
|
||
} else {
|
||
console.log(`列 ${tableName}.${columnName} 已存在`);
|
||
}
|
||
};
|
||
|
||
const ensureTable = async (createTableSql: string) => {
|
||
await exec(createTableSql);
|
||
};
|
||
|
||
const ensureIndex = async (createIndexSql: string) => {
|
||
await exec(createIndexSql);
|
||
};
|
||
|
||
const ensureUserGroupSchemaAndAllUsersMembership = async () => {
|
||
// 1) Ensure tables
|
||
await ensureTable(`
|
||
CREATE TABLE IF NOT EXISTS user_groups (
|
||
id TEXT PRIMARY KEY,
|
||
name TEXT UNIQUE NOT NULL,
|
||
description TEXT NOT NULL DEFAULT '',
|
||
is_system BOOLEAN NOT NULL DEFAULT 0,
|
||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
`);
|
||
|
||
await ensureTable(`
|
||
CREATE TABLE IF NOT EXISTS user_group_members (
|
||
group_id TEXT NOT NULL,
|
||
user_id TEXT NOT NULL,
|
||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
||
PRIMARY KEY (group_id, user_id),
|
||
FOREIGN KEY (group_id) REFERENCES user_groups(id) ON DELETE CASCADE,
|
||
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
|
||
);
|
||
`);
|
||
|
||
// 2) Ensure indexes
|
||
await ensureIndex(
|
||
`CREATE INDEX IF NOT EXISTS idx_user_group_members_group_id ON user_group_members(group_id);`,
|
||
);
|
||
await ensureIndex(
|
||
`CREATE INDEX IF NOT EXISTS idx_user_group_members_user_id ON user_group_members(user_id);`,
|
||
);
|
||
|
||
// 3) Ensure system group exists
|
||
const existingSystemGroup = await get(
|
||
`SELECT id FROM user_groups WHERE is_system = 1 ORDER BY created_at ASC LIMIT 1`,
|
||
);
|
||
|
||
let systemGroupId = existingSystemGroup?.id as string | undefined;
|
||
if (!systemGroupId) {
|
||
const preferredId = 'all-users';
|
||
try {
|
||
await run(
|
||
`INSERT INTO user_groups (id, name, description, is_system) VALUES (?, ?, ?, 1)`,
|
||
[preferredId, '全体用户', '系统内置:新用户自动加入'],
|
||
);
|
||
systemGroupId = preferredId;
|
||
} catch {
|
||
const fallbackId = uuidv4();
|
||
await run(
|
||
`INSERT INTO user_groups (id, name, description, is_system) VALUES (?, ?, ?, 1)`,
|
||
[fallbackId, '全体用户', '系统内置:新用户自动加入'],
|
||
);
|
||
systemGroupId = fallbackId;
|
||
}
|
||
}
|
||
|
||
// 4) Backfill membership: ensure all existing users are in the system group
|
||
if (systemGroupId) {
|
||
await run(
|
||
`INSERT OR IGNORE INTO user_group_members (group_id, user_id)
|
||
SELECT ?, u.id FROM users u`,
|
||
[systemGroupId],
|
||
);
|
||
}
|
||
};
|
||
|
||
const getTableCreateSql = async (tableName: string): Promise<string> => {
|
||
const row = await get(
|
||
`SELECT sql FROM sqlite_master WHERE type='table' AND name=? LIMIT 1`,
|
||
[tableName],
|
||
);
|
||
return (row?.sql as string | undefined) ?? '';
|
||
};
|
||
|
||
const tableSqlHasScoreGreaterThanZeroCheck = (tableSql: string): boolean => {
|
||
if (!tableSql) return false;
|
||
// 兼容不同空白/大小写写法:CHECK(score > 0) / CHECK ( score>0 )
|
||
return /check\s*\(\s*score\s*>\s*0\s*\)/i.test(tableSql);
|
||
};
|
||
|
||
const migrateQuestionsScoreCheckToAllowZero = async () => {
|
||
const questionsSql = await getTableCreateSql('questions');
|
||
if (!tableSqlHasScoreGreaterThanZeroCheck(questionsSql)) return;
|
||
|
||
console.log('检测到旧表约束:questions.score CHECK(score > 0),开始迁移为 >= 0');
|
||
|
||
// 迁移方式:重建 questions 表(SQLite 不支持直接修改 CHECK 约束)
|
||
// 注意:questions 被 quiz_answers 外键引用,因此迁移期间临时关闭 foreign_keys。
|
||
await exec('PRAGMA foreign_keys = OFF;');
|
||
try {
|
||
await exec('BEGIN TRANSACTION;');
|
||
|
||
await exec(`
|
||
CREATE TABLE IF NOT EXISTS questions_new (
|
||
id TEXT PRIMARY KEY,
|
||
content TEXT NOT NULL,
|
||
type TEXT NOT NULL CHECK(type IN ('single', 'multiple', 'judgment', 'text')),
|
||
options TEXT,
|
||
answer TEXT NOT NULL,
|
||
analysis TEXT NOT NULL DEFAULT '',
|
||
score INTEGER NOT NULL CHECK(score >= 0),
|
||
category TEXT NOT NULL DEFAULT '通用',
|
||
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
`);
|
||
|
||
await exec(`
|
||
INSERT INTO questions_new (id, content, type, options, answer, analysis, score, category, created_at)
|
||
SELECT
|
||
id,
|
||
content,
|
||
type,
|
||
options,
|
||
COALESCE(answer, ''),
|
||
COALESCE(analysis, ''),
|
||
score,
|
||
COALESCE(category, '通用'),
|
||
created_at
|
||
FROM questions;
|
||
`);
|
||
|
||
await exec('DROP TABLE questions;');
|
||
await exec('ALTER TABLE questions_new RENAME TO questions;');
|
||
|
||
await exec('CREATE INDEX IF NOT EXISTS idx_questions_type ON questions(type);');
|
||
await exec('CREATE INDEX IF NOT EXISTS idx_questions_score ON questions(score);');
|
||
await exec('CREATE INDEX IF NOT EXISTS idx_questions_category ON questions(category);');
|
||
|
||
await exec('COMMIT;');
|
||
console.log('questions 表迁移完成:score 允许 0 分');
|
||
} catch (error) {
|
||
try {
|
||
await exec('ROLLBACK;');
|
||
} catch {
|
||
// ignore
|
||
}
|
||
throw error;
|
||
} finally {
|
||
await exec('PRAGMA foreign_keys = ON;');
|
||
}
|
||
};
|
||
|
||
const migrateDatabase = async () => {
|
||
await migrateQuestionsScoreCheckToAllowZero();
|
||
};
|
||
|
||
// 数据库初始化函数
|
||
export const initDatabase = async () => {
|
||
try {
|
||
// 确保数据库连接已初始化
|
||
await initDbConnection();
|
||
|
||
// 检查是否需要初始化:如果users表不存在,则执行初始化
|
||
const usersTableExists = await tableExists('users');
|
||
|
||
if (!usersTableExists) {
|
||
// 读取并执行初始化SQL文件
|
||
const initSqlPath = fileURLToPath(new URL('./init.sql', import.meta.url));
|
||
const initSql = fs.readFileSync(initSqlPath, 'utf8');
|
||
|
||
await exec(initSql);
|
||
console.log('数据库初始化成功');
|
||
|
||
// 用户组(含“全体用户”系统组)
|
||
await ensureUserGroupSchemaAndAllUsersMembership();
|
||
} else {
|
||
console.log('数据库表已存在,跳过初始化');
|
||
await ensureColumn('questions', "analysis TEXT NOT NULL DEFAULT ''", 'analysis');
|
||
await ensureColumn('quiz_records', "score_percentage REAL", 'score_percentage');
|
||
await ensureColumn('quiz_records', "status TEXT", 'status');
|
||
|
||
// 兼容历史数据库:迁移无法通过 init.sql 修复的约束/结构
|
||
await migrateDatabase();
|
||
|
||
// 用户组(含“全体用户”系统组)
|
||
await ensureUserGroupSchemaAndAllUsersMembership();
|
||
}
|
||
} catch (error) {
|
||
console.error('数据库初始化失败:', error);
|
||
// 即使初始化失败,服务器也应该继续运行
|
||
}
|
||
};
|
||
|
||
// 数据库查询工具函数
|
||
export const query = async (sql: string, params: any[] = []): Promise<any[]> => {
|
||
return new Promise(async (resolve, reject) => {
|
||
const db = await getDb();
|
||
if (!db) {
|
||
reject(new Error('数据库连接未初始化'));
|
||
return;
|
||
}
|
||
db.all(sql, params, (err: Error, rows: any[]) => {
|
||
if (err) {
|
||
reject(err);
|
||
} else {
|
||
resolve(rows);
|
||
}
|
||
});
|
||
});
|
||
};
|
||
|
||
// all函数是query函数的别名,用于向后兼容
|
||
export const all = query;
|
||
|
||
export const run = async (sql: string, params: any[] = []): Promise<{ id: string }> => {
|
||
return new Promise(async (resolve, reject) => {
|
||
const db = await getDb();
|
||
if (!db) {
|
||
reject(new Error('数据库连接未初始化'));
|
||
return;
|
||
}
|
||
db.run(sql, params, function(this: any, err: Error | null) {
|
||
if (err) {
|
||
reject(err);
|
||
} else {
|
||
resolve({ id: this.lastID ? this.lastID.toString() : '' });
|
||
}
|
||
});
|
||
});
|
||
};
|
||
|
||
export const get = async (sql: string, params: any[] = []): Promise<any> => {
|
||
return new Promise(async (resolve, reject) => {
|
||
const db = await getDb();
|
||
if (!db) {
|
||
reject(new Error('数据库连接未初始化'));
|
||
return;
|
||
}
|
||
db.get(sql, params, (err: Error, row: any) => {
|
||
if (err) {
|
||
reject(err);
|
||
} else {
|
||
resolve(row);
|
||
}
|
||
});
|
||
});
|
||
};
|