mxivideo/init-scripts/01-init-database.sql

127 lines
4.9 KiB
PL/PgSQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 初始化 MixVideo 数据库
-- 这个脚本会在 PostgreSQL 容器首次启动时自动执行
-- 创建扩展
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
CREATE EXTENSION IF NOT EXISTS "pg_trgm";
-- 创建用户表
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
username VARCHAR(50) UNIQUE NOT NULL,
email VARCHAR(100) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
access_token VARCHAR(500),
token_expires_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
is_active BOOLEAN DEFAULT true
);
-- 创建模板表
CREATE TABLE IF NOT EXISTS templates (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
description TEXT,
thumbnail_path VARCHAR(500),
draft_content_path VARCHAR(500),
resources_path VARCHAR(500),
canvas_config JSONB DEFAULT '{}',
duration INTEGER DEFAULT 0,
material_count INTEGER DEFAULT 0,
track_count INTEGER DEFAULT 0,
tags TEXT[] DEFAULT '{}',
is_cloud BOOLEAN DEFAULT false,
user_id VARCHAR(100) NOT NULL DEFAULT 'default',
draft_content JSONB,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- 创建资源分类表
CREATE TABLE IF NOT EXISTS resource_categories (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
title VARCHAR(255) NOT NULL,
ai_prompt TEXT NOT NULL,
color VARCHAR(7) NOT NULL DEFAULT '#FF6B6B',
is_active BOOLEAN DEFAULT true,
is_cloud BOOLEAN DEFAULT false,
user_id VARCHAR(100) NOT NULL DEFAULT 'default',
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- 创建项目表
CREATE TABLE IF NOT EXISTS projects (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
description TEXT,
project_directory VARCHAR(500),
thumbnail_path VARCHAR(500),
canvas_config JSONB DEFAULT '{}',
user_id VARCHAR(100) NOT NULL DEFAULT 'default',
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- 创建索引
CREATE INDEX IF NOT EXISTS idx_users_username ON users(username);
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
CREATE INDEX IF NOT EXISTS idx_users_access_token ON users(access_token);
CREATE INDEX IF NOT EXISTS idx_templates_user_id ON templates(user_id);
CREATE INDEX IF NOT EXISTS idx_templates_name ON templates(name);
CREATE INDEX IF NOT EXISTS idx_templates_is_cloud ON templates(is_cloud);
CREATE INDEX IF NOT EXISTS idx_templates_created_at ON templates(created_at);
CREATE INDEX IF NOT EXISTS idx_resource_categories_user_id ON resource_categories(user_id);
CREATE INDEX IF NOT EXISTS idx_resource_categories_is_active ON resource_categories(is_active);
CREATE INDEX IF NOT EXISTS idx_resource_categories_is_cloud ON resource_categories(is_cloud);
CREATE INDEX IF NOT EXISTS idx_projects_user_id ON projects(user_id);
CREATE INDEX IF NOT EXISTS idx_projects_name ON projects(name);
-- 插入默认数据
INSERT INTO users (id, username, email, password_hash, access_token)
VALUES (
'default-user-id',
'default',
'default@mixvideo.com',
'default_hash',
'default_token'
) ON CONFLICT (username) DO NOTHING;
-- 插入默认分类
INSERT INTO resource_categories (title, ai_prompt, color, user_id) VALUES
('开场介绍', '视频开头的介绍部分包括标题、logo等', '#FF6B6B', 'default'),
('主要内容', '视频的核心内容部分', '#4ECDC4', 'default'),
('转场过渡', '视频片段之间的过渡效果', '#45B7D1', 'default'),
('结尾总结', '视频结尾的总结和结束语', '#96CEB4', 'default'),
('背景音乐', '视频的背景音乐和音效', '#FFEAA7', 'default'),
('字幕文本', '视频中的字幕和文字说明', '#DDA0DD', 'default'),
('特效动画', '视频中的特效和动画效果', '#98D8C8', 'default'),
('产品展示', '产品或服务的展示片段', '#F7DC6F', 'default')
ON CONFLICT DO NOTHING;
-- 创建更新时间触发器函数
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
-- 为所有表创建更新时间触发器
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_templates_updated_at BEFORE UPDATE ON templates
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_resource_categories_updated_at BEFORE UPDATE ON resource_categories
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_projects_updated_at BEFORE UPDATE ON projects
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();