mirror of
https://github.com/MoonTechLab/LunaTV.git
synced 2026-02-21 09:14:42 +08:00
feat: add d1 support (untested)
This commit is contained in:
547
src/lib/d1.db.ts
Normal file
547
src/lib/d1.db.ts
Normal file
@@ -0,0 +1,547 @@
|
||||
/* eslint-disable no-console, @typescript-eslint/no-explicit-any, @typescript-eslint/no-non-null-assertion */
|
||||
|
||||
import { AdminConfig } from './admin.types';
|
||||
import { Favorite, IStorage, PlayRecord } from './types';
|
||||
|
||||
// 搜索历史最大条数
|
||||
const SEARCH_HISTORY_LIMIT = 20;
|
||||
|
||||
// D1 数据库接口
|
||||
interface D1Database {
|
||||
prepare(sql: string): D1PreparedStatement;
|
||||
exec(sql: string): Promise<D1ExecResult>;
|
||||
batch(statements: D1PreparedStatement[]): Promise<D1Result[]>;
|
||||
}
|
||||
|
||||
interface D1PreparedStatement {
|
||||
bind(...values: any[]): D1PreparedStatement;
|
||||
first<T = any>(colName?: string): Promise<T | null>;
|
||||
run(): Promise<D1Result>;
|
||||
all<T = any>(): Promise<D1Result<T>>;
|
||||
}
|
||||
|
||||
interface D1Result<T = any> {
|
||||
results: T[];
|
||||
success: boolean;
|
||||
error?: string;
|
||||
meta: {
|
||||
changed_db: boolean;
|
||||
changes: number;
|
||||
last_row_id: number;
|
||||
duration: number;
|
||||
};
|
||||
}
|
||||
|
||||
interface D1ExecResult {
|
||||
count: number;
|
||||
duration: number;
|
||||
}
|
||||
|
||||
// 数据库初始化 SQL
|
||||
const INIT_SQL = `
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
username TEXT PRIMARY KEY,
|
||||
password TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS play_records (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
username TEXT NOT NULL,
|
||||
key TEXT NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
source_name TEXT NOT NULL,
|
||||
cover TEXT NOT NULL,
|
||||
year TEXT NOT NULL,
|
||||
index_episode INTEGER NOT NULL,
|
||||
total_episodes INTEGER NOT NULL,
|
||||
play_time INTEGER NOT NULL,
|
||||
total_time INTEGER NOT NULL,
|
||||
save_time INTEGER NOT NULL,
|
||||
search_title TEXT,
|
||||
UNIQUE(username, key)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS favorites (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
username TEXT NOT NULL,
|
||||
key TEXT NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
source_name TEXT NOT NULL,
|
||||
cover TEXT NOT NULL,
|
||||
year TEXT NOT NULL,
|
||||
total_episodes INTEGER NOT NULL,
|
||||
save_time INTEGER NOT NULL,
|
||||
UNIQUE(username, key)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS search_history (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
username TEXT NOT NULL,
|
||||
keyword TEXT NOT NULL,
|
||||
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),
|
||||
UNIQUE(username, keyword)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS admin_config (
|
||||
id INTEGER PRIMARY KEY DEFAULT 1,
|
||||
config TEXT NOT NULL,
|
||||
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
|
||||
);
|
||||
|
||||
-- 基本索引
|
||||
CREATE INDEX IF NOT EXISTS idx_play_records_username ON play_records(username);
|
||||
CREATE INDEX IF NOT EXISTS idx_favorites_username ON favorites(username);
|
||||
CREATE INDEX IF NOT EXISTS idx_search_history_username ON search_history(username);
|
||||
|
||||
-- 复合索引优化查询性能
|
||||
-- 播放记录:用户名+键值的复合索引,用于快速查找特定记录
|
||||
CREATE INDEX IF NOT EXISTS idx_play_records_username_key ON play_records(username, key);
|
||||
-- 播放记录:用户名+保存时间的复合索引,用于按时间排序的查询
|
||||
CREATE INDEX IF NOT EXISTS idx_play_records_username_save_time ON play_records(username, save_time DESC);
|
||||
|
||||
-- 收藏:用户名+键值的复合索引,用于快速查找特定收藏
|
||||
CREATE INDEX IF NOT EXISTS idx_favorites_username_key ON favorites(username, key);
|
||||
-- 收藏:用户名+保存时间的复合索引,用于按时间排序的查询
|
||||
CREATE INDEX IF NOT EXISTS idx_favorites_username_save_time ON favorites(username, save_time DESC);
|
||||
|
||||
-- 搜索历史:用户名+关键词的复合索引,用于快速查找/删除特定搜索记录
|
||||
CREATE INDEX IF NOT EXISTS idx_search_history_username_keyword ON search_history(username, keyword);
|
||||
-- 搜索历史:用户名+创建时间的复合索引,用于按时间排序的查询
|
||||
CREATE INDEX IF NOT EXISTS idx_search_history_username_created_at ON search_history(username, created_at DESC);
|
||||
|
||||
-- 搜索历史清理查询的优化索引
|
||||
CREATE INDEX IF NOT EXISTS idx_search_history_username_id_created_at ON search_history(username, id, created_at DESC);
|
||||
`;
|
||||
|
||||
// 获取全局D1数据库实例
|
||||
function getD1Database(): D1Database {
|
||||
// 在 next-on-pages 环境中,D1 数据库通过 process.env 暴露
|
||||
if (typeof process !== 'undefined' && (process.env as any).DB) {
|
||||
return (process.env as any).DB as D1Database;
|
||||
}
|
||||
throw new Error(
|
||||
'D1 database not available. Make sure DB is bound in wrangler.toml'
|
||||
);
|
||||
}
|
||||
|
||||
export class D1Storage implements IStorage {
|
||||
private db: D1Database;
|
||||
|
||||
constructor() {
|
||||
this.db = getD1Database();
|
||||
this.initDatabase();
|
||||
}
|
||||
|
||||
private async initDatabase() {
|
||||
try {
|
||||
await this.db.exec(INIT_SQL);
|
||||
} catch (err) {
|
||||
console.error('Failed to initialize D1 database:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 播放记录相关
|
||||
async getPlayRecord(
|
||||
userName: string,
|
||||
key: string
|
||||
): Promise<PlayRecord | null> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT * FROM play_records WHERE username = ? AND key = ?')
|
||||
.bind(userName, key)
|
||||
.first<any>();
|
||||
|
||||
if (!result) return null;
|
||||
|
||||
return {
|
||||
title: result.title,
|
||||
source_name: result.source_name,
|
||||
cover: result.cover,
|
||||
year: result.year,
|
||||
index: result.index_episode,
|
||||
total_episodes: result.total_episodes,
|
||||
play_time: result.play_time,
|
||||
total_time: result.total_time,
|
||||
save_time: result.save_time,
|
||||
search_title: result.search_title || undefined,
|
||||
};
|
||||
} catch (err) {
|
||||
console.error('Failed to get play record:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async setPlayRecord(
|
||||
userName: string,
|
||||
key: string,
|
||||
record: PlayRecord
|
||||
): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare(
|
||||
`
|
||||
INSERT OR REPLACE INTO play_records
|
||||
(username, key, title, source_name, cover, year, index_episode, total_episodes, play_time, total_time, save_time, search_title)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
|
||||
`
|
||||
)
|
||||
.bind(
|
||||
userName,
|
||||
key,
|
||||
record.title,
|
||||
record.source_name,
|
||||
record.cover,
|
||||
record.year,
|
||||
record.index,
|
||||
record.total_episodes,
|
||||
record.play_time,
|
||||
record.total_time,
|
||||
record.save_time,
|
||||
record.search_title || null
|
||||
)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to set play record:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async getAllPlayRecords(
|
||||
userName: string
|
||||
): Promise<Record<string, PlayRecord>> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare(
|
||||
'SELECT * FROM play_records WHERE username = ? ORDER BY save_time DESC'
|
||||
)
|
||||
.bind(userName)
|
||||
.all<any>();
|
||||
|
||||
const records: Record<string, PlayRecord> = {};
|
||||
|
||||
result.results.forEach((row: any) => {
|
||||
records[row.key] = {
|
||||
title: row.title,
|
||||
source_name: row.source_name,
|
||||
cover: row.cover,
|
||||
year: row.year,
|
||||
index: row.index_episode,
|
||||
total_episodes: row.total_episodes,
|
||||
play_time: row.play_time,
|
||||
total_time: row.total_time,
|
||||
save_time: row.save_time,
|
||||
search_title: row.search_title || undefined,
|
||||
};
|
||||
});
|
||||
|
||||
return records;
|
||||
} catch (err) {
|
||||
console.error('Failed to get all play records:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async deletePlayRecord(userName: string, key: string): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare('DELETE FROM play_records WHERE username = ? AND key = ?')
|
||||
.bind(userName, key)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to delete play record:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 收藏相关
|
||||
async getFavorite(userName: string, key: string): Promise<Favorite | null> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT * FROM favorites WHERE username = ? AND key = ?')
|
||||
.bind(userName, key)
|
||||
.first<any>();
|
||||
|
||||
if (!result) return null;
|
||||
|
||||
return {
|
||||
title: result.title,
|
||||
source_name: result.source_name,
|
||||
cover: result.cover,
|
||||
year: result.year,
|
||||
total_episodes: result.total_episodes,
|
||||
save_time: result.save_time,
|
||||
};
|
||||
} catch (err) {
|
||||
console.error('Failed to get favorite:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async setFavorite(
|
||||
userName: string,
|
||||
key: string,
|
||||
favorite: Favorite
|
||||
): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare(
|
||||
`
|
||||
INSERT OR REPLACE INTO favorites
|
||||
(username, key, title, source_name, cover, year, total_episodes, save_time)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?)
|
||||
`
|
||||
)
|
||||
.bind(
|
||||
userName,
|
||||
key,
|
||||
favorite.title,
|
||||
favorite.source_name,
|
||||
favorite.cover,
|
||||
favorite.year,
|
||||
favorite.total_episodes,
|
||||
favorite.save_time
|
||||
)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to set favorite:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async getAllFavorites(userName: string): Promise<Record<string, Favorite>> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare(
|
||||
'SELECT * FROM favorites WHERE username = ? ORDER BY save_time DESC'
|
||||
)
|
||||
.bind(userName)
|
||||
.all<any>();
|
||||
|
||||
const favorites: Record<string, Favorite> = {};
|
||||
|
||||
result.results.forEach((row: any) => {
|
||||
favorites[row.key] = {
|
||||
title: row.title,
|
||||
source_name: row.source_name,
|
||||
cover: row.cover,
|
||||
year: row.year,
|
||||
total_episodes: row.total_episodes,
|
||||
save_time: row.save_time,
|
||||
};
|
||||
});
|
||||
|
||||
return favorites;
|
||||
} catch (err) {
|
||||
console.error('Failed to get all favorites:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async deleteFavorite(userName: string, key: string): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare('DELETE FROM favorites WHERE username = ? AND key = ?')
|
||||
.bind(userName, key)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to delete favorite:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 用户相关
|
||||
async registerUser(userName: string, password: string): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare('INSERT INTO users (username, password) VALUES (?, ?)')
|
||||
.bind(userName, password)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to register user:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async verifyUser(userName: string, password: string): Promise<boolean> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT password FROM users WHERE username = ?')
|
||||
.bind(userName)
|
||||
.first<{ password: string }>();
|
||||
|
||||
return result?.password === password;
|
||||
} catch (err) {
|
||||
console.error('Failed to verify user:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async checkUserExist(userName: string): Promise<boolean> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT 1 FROM users WHERE username = ?')
|
||||
.bind(userName)
|
||||
.first();
|
||||
|
||||
return result !== null;
|
||||
} catch (err) {
|
||||
console.error('Failed to check user existence:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async changePassword(userName: string, newPassword: string): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare('UPDATE users SET password = ? WHERE username = ?')
|
||||
.bind(newPassword, userName)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to change password:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async deleteUser(userName: string): Promise<void> {
|
||||
try {
|
||||
const statements = [
|
||||
this.db.prepare('DELETE FROM users WHERE username = ?').bind(userName),
|
||||
this.db
|
||||
.prepare('DELETE FROM play_records WHERE username = ?')
|
||||
.bind(userName),
|
||||
this.db
|
||||
.prepare('DELETE FROM favorites WHERE username = ?')
|
||||
.bind(userName),
|
||||
this.db
|
||||
.prepare('DELETE FROM search_history WHERE username = ?')
|
||||
.bind(userName),
|
||||
];
|
||||
|
||||
await this.db.batch(statements);
|
||||
} catch (err) {
|
||||
console.error('Failed to delete user:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 搜索历史相关
|
||||
async getSearchHistory(userName: string): Promise<string[]> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare(
|
||||
'SELECT keyword FROM search_history WHERE username = ? ORDER BY created_at DESC LIMIT ?'
|
||||
)
|
||||
.bind(userName, SEARCH_HISTORY_LIMIT)
|
||||
.all<{ keyword: string }>();
|
||||
|
||||
return result.results.map((row) => row.keyword);
|
||||
} catch (err) {
|
||||
console.error('Failed to get search history:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async addSearchHistory(userName: string, keyword: string): Promise<void> {
|
||||
try {
|
||||
// 先删除可能存在的重复记录
|
||||
await this.db
|
||||
.prepare(
|
||||
'DELETE FROM search_history WHERE username = ? AND keyword = ?'
|
||||
)
|
||||
.bind(userName, keyword)
|
||||
.run();
|
||||
|
||||
// 添加新记录
|
||||
await this.db
|
||||
.prepare('INSERT INTO search_history (username, keyword) VALUES (?, ?)')
|
||||
.bind(userName, keyword)
|
||||
.run();
|
||||
|
||||
// 保持历史记录条数限制
|
||||
await this.db
|
||||
.prepare(
|
||||
`
|
||||
DELETE FROM search_history
|
||||
WHERE username = ? AND id NOT IN (
|
||||
SELECT id FROM search_history
|
||||
WHERE username = ?
|
||||
ORDER BY created_at DESC
|
||||
LIMIT ?
|
||||
)
|
||||
`
|
||||
)
|
||||
.bind(userName, userName, SEARCH_HISTORY_LIMIT)
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to add search history:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async deleteSearchHistory(userName: string, keyword?: string): Promise<void> {
|
||||
try {
|
||||
if (keyword) {
|
||||
await this.db
|
||||
.prepare(
|
||||
'DELETE FROM search_history WHERE username = ? AND keyword = ?'
|
||||
)
|
||||
.bind(userName, keyword)
|
||||
.run();
|
||||
} else {
|
||||
await this.db
|
||||
.prepare('DELETE FROM search_history WHERE username = ?')
|
||||
.bind(userName)
|
||||
.run();
|
||||
}
|
||||
} catch (err) {
|
||||
console.error('Failed to delete search history:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 用户列表
|
||||
async getAllUsers(): Promise<string[]> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT username FROM users ORDER BY created_at ASC')
|
||||
.all<{ username: string }>();
|
||||
|
||||
return result.results.map((row) => row.username);
|
||||
} catch (err) {
|
||||
console.error('Failed to get all users:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
// 管理员配置相关
|
||||
async getAdminConfig(): Promise<AdminConfig | null> {
|
||||
try {
|
||||
const result = await this.db
|
||||
.prepare('SELECT config FROM admin_config WHERE id = 1')
|
||||
.first<{ config: string }>();
|
||||
|
||||
if (!result) return null;
|
||||
|
||||
return JSON.parse(result.config) as AdminConfig;
|
||||
} catch (err) {
|
||||
console.error('Failed to get admin config:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
|
||||
async setAdminConfig(config: AdminConfig): Promise<void> {
|
||||
try {
|
||||
await this.db
|
||||
.prepare(
|
||||
'INSERT OR REPLACE INTO admin_config (id, config) VALUES (1, ?)'
|
||||
)
|
||||
.bind(JSON.stringify(config))
|
||||
.run();
|
||||
} catch (err) {
|
||||
console.error('Failed to set admin config:', err);
|
||||
throw err;
|
||||
}
|
||||
}
|
||||
}
|
||||
@@ -35,7 +35,7 @@ const STORAGE_TYPE = (() => {
|
||||
const raw =
|
||||
(typeof window !== 'undefined' &&
|
||||
(window as any).RUNTIME_CONFIG?.STORAGE_TYPE) ||
|
||||
(process.env.STORAGE_TYPE as 'localstorage' | 'redis' | undefined) ||
|
||||
(process.env.STORAGE_TYPE as 'localstorage' | 'redis' | 'd1' | undefined) ||
|
||||
'localstorage';
|
||||
// 兼容 redis => database
|
||||
return raw;
|
||||
|
||||
@@ -1,14 +1,16 @@
|
||||
/* eslint-disable no-console, @typescript-eslint/no-explicit-any, @typescript-eslint/no-non-null-assertion */
|
||||
|
||||
import { AdminConfig } from './admin.types';
|
||||
import { D1Storage } from './d1.db';
|
||||
import { RedisStorage } from './redis.db';
|
||||
import { Favorite, IStorage, PlayRecord } from './types';
|
||||
|
||||
// storage type 常量: 'localstorage' | 'database',默认 'localstorage'
|
||||
// storage type 常量: 'localstorage' | 'redis' | 'd1',默认 'localstorage'
|
||||
const STORAGE_TYPE =
|
||||
(process.env.NEXT_PUBLIC_STORAGE_TYPE as
|
||||
| 'localstorage'
|
||||
| 'redis'
|
||||
| 'd1'
|
||||
| undefined) || 'localstorage';
|
||||
|
||||
// 创建存储实例
|
||||
@@ -16,6 +18,8 @@ function createStorage(): IStorage {
|
||||
switch (STORAGE_TYPE) {
|
||||
case 'redis':
|
||||
return new RedisStorage();
|
||||
case 'd1':
|
||||
return new D1Storage();
|
||||
case 'localstorage':
|
||||
default:
|
||||
// 默认返回内存实现,保证本地开发可用
|
||||
|
||||
Reference in New Issue
Block a user