Twilioapp-project/web-app/database-init.sql
mars 0d57273021 添加数据库集成和用户认证功能
- 新增用户注册和登录系统 (login.html, register.html)
- 集成Supabase数据库连接 (config.js, api.js)
- 完善数据库架构设计 (database-schema.sql)
- 添加部署指南和配置文档 (DEPLOYMENT_GUIDE.md)
- 修复主页面结构和功能完善 (index.html)
- 支持通话记录保存到数据库
- 完整的账单管理和用户认证流程
- 集成OpenAI、Twilio、Stripe等API服务
2025-06-30 19:34:58 +08:00

199 lines
10 KiB
PL/PgSQL

-- 翻译服务应用数据库初始化脚本
-- 适用于 Supabase PostgreSQL
-- 1. 创建更新时间触发器函数
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- 2. 创建用户档案表
CREATE TABLE IF NOT EXISTS user_profiles (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
username VARCHAR(50) UNIQUE NOT NULL,
full_name VARCHAR(100) NOT NULL,
email VARCHAR(255) UNIQUE NOT NULL,
phone VARCHAR(20),
avatar_url TEXT,
preferred_language VARCHAR(10) DEFAULT 'zh-CN',
timezone VARCHAR(50) DEFAULT 'Asia/Shanghai',
account_balance DECIMAL(10,2) DEFAULT 0.00,
is_verified BOOLEAN DEFAULT false,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 3. 创建翻译员档案表
CREATE TABLE IF NOT EXISTS translator_profiles (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
specializations TEXT[] DEFAULT '{}',
languages TEXT[] DEFAULT '{}',
hourly_rate DECIMAL(8,2) DEFAULT 50.00,
rating DECIMAL(3,2) DEFAULT 0.00,
total_reviews INTEGER DEFAULT 0,
is_available BOOLEAN DEFAULT true,
certification_level VARCHAR(20) DEFAULT 'basic',
experience_years INTEGER DEFAULT 0,
bio TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 4. 创建通话记录表
CREATE TABLE IF NOT EXISTS call_records (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE SET NULL,
call_type VARCHAR(20) NOT NULL CHECK (call_type IN ('voice', 'video')),
duration_minutes INTEGER NOT NULL DEFAULT 0,
base_rate DECIMAL(8,2) NOT NULL,
translator_rate DECIMAL(8,2) DEFAULT 0.00,
total_amount DECIMAL(10,2) NOT NULL,
status VARCHAR(20) DEFAULT 'completed' CHECK (status IN ('active', 'completed', 'cancelled')),
quality_rating INTEGER CHECK (quality_rating >= 1 AND quality_rating <= 5),
feedback TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
ended_at TIMESTAMP WITH TIME ZONE
);
-- 5. 创建预约表
CREATE TABLE IF NOT EXISTS appointments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE CASCADE,
appointment_date TIMESTAMP WITH TIME ZONE NOT NULL,
duration_minutes INTEGER DEFAULT 60,
service_type VARCHAR(50) NOT NULL,
languages TEXT[] NOT NULL,
special_requirements TEXT,
status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'confirmed', 'cancelled', 'completed')),
total_amount DECIMAL(10,2) NOT NULL,
notes TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 6. 创建文档翻译表
CREATE TABLE IF NOT EXISTS document_translations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE SET NULL,
original_filename VARCHAR(255) NOT NULL,
translated_filename VARCHAR(255),
file_size INTEGER NOT NULL,
file_type VARCHAR(50) NOT NULL,
source_language VARCHAR(10) NOT NULL,
target_language VARCHAR(10) NOT NULL,
word_count INTEGER DEFAULT 0,
status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
total_amount DECIMAL(10,2) NOT NULL,
completion_percentage INTEGER DEFAULT 0,
estimated_completion TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 7. 创建支付记录表
CREATE TABLE IF NOT EXISTS payments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
related_table VARCHAR(50) NOT NULL,
related_id UUID NOT NULL,
amount DECIMAL(10,2) NOT NULL,
currency VARCHAR(3) DEFAULT 'CNY',
payment_method VARCHAR(20) NOT NULL,
payment_status VARCHAR(20) DEFAULT 'pending' CHECK (payment_status IN ('pending', 'processing', 'completed', 'failed', 'refunded')),
stripe_payment_intent_id TEXT,
transaction_id VARCHAR(100),
paid_at TIMESTAMP WITH TIME ZONE,
refunded_at TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 8. 创建系统设置表
CREATE TABLE IF NOT EXISTS system_settings (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
setting_key VARCHAR(100) UNIQUE NOT NULL,
setting_value TEXT NOT NULL,
setting_type VARCHAR(20) DEFAULT 'string' CHECK (setting_type IN ('string', 'number', 'boolean', 'json')),
description TEXT,
is_public BOOLEAN DEFAULT false,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 9. 创建触发器
CREATE TRIGGER update_user_profiles_updated_at BEFORE UPDATE ON user_profiles FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TRIGGER update_translator_profiles_updated_at BEFORE UPDATE ON translator_profiles FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TRIGGER update_appointments_updated_at BEFORE UPDATE ON appointments FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TRIGGER update_document_translations_updated_at BEFORE UPDATE ON document_translations FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
CREATE TRIGGER update_system_settings_updated_at BEFORE UPDATE ON system_settings FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
-- 10. 启用行级安全 (RLS)
ALTER TABLE user_profiles ENABLE ROW LEVEL SECURITY;
ALTER TABLE translator_profiles ENABLE ROW LEVEL SECURITY;
ALTER TABLE call_records ENABLE ROW LEVEL SECURITY;
ALTER TABLE appointments ENABLE ROW LEVEL SECURITY;
ALTER TABLE document_translations ENABLE ROW LEVEL SECURITY;
ALTER TABLE payments ENABLE ROW LEVEL SECURITY;
-- 11. 创建 RLS 策略
-- 用户档案策略
CREATE POLICY "用户只能查看自己的档案" ON user_profiles FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "用户只能更新自己的档案" ON user_profiles FOR UPDATE USING (auth.uid() = user_id);
CREATE POLICY "用户可以插入自己的档案" ON user_profiles FOR INSERT WITH CHECK (auth.uid() = user_id);
-- 翻译员档案策略
CREATE POLICY "翻译员只能查看自己的档案" ON translator_profiles FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "翻译员只能更新自己的档案" ON translator_profiles FOR UPDATE USING (auth.uid() = user_id);
CREATE POLICY "翻译员可以插入自己的档案" ON translator_profiles FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "所有用户可以查看翻译员档案" ON translator_profiles FOR SELECT USING (true);
-- 通话记录策略
CREATE POLICY "用户只能查看自己的通话记录" ON call_records FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "用户可以插入自己的通话记录" ON call_records FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "用户可以更新自己的通话记录" ON call_records FOR UPDATE USING (auth.uid() = user_id);
-- 预约策略
CREATE POLICY "用户只能查看自己的预约" ON appointments FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "用户可以插入自己的预约" ON appointments FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "用户可以更新自己的预约" ON appointments FOR UPDATE USING (auth.uid() = user_id);
-- 文档翻译策略
CREATE POLICY "用户只能查看自己的文档翻译" ON document_translations FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "用户可以插入自己的文档翻译" ON document_translations FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "用户可以更新自己的文档翻译" ON document_translations FOR UPDATE USING (auth.uid() = user_id);
-- 支付记录策略
CREATE POLICY "用户只能查看自己的支付记录" ON payments FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "用户可以插入自己的支付记录" ON payments FOR INSERT WITH CHECK (auth.uid() = user_id);
-- 12. 插入默认系统设置
INSERT INTO system_settings (setting_key, setting_value, setting_type, description, is_public) VALUES
('voice_call_rate', '80.00', 'number', '语音通话费率(元/小时)', true),
('video_call_rate', '120.00', 'number', '视频通话费率(元/小时)', true),
('translator_rate', '50.00', 'number', '翻译员费率(元/小时)', true),
('min_call_duration', '1', 'number', '最小通话时长(分钟)', true),
('supported_languages', '["zh-CN", "en-US", "ja-JP", "ko-KR", "fr-FR", "de-DE", "es-ES", "it-IT", "pt-PT", "ru-RU"]', 'json', '支持的语言列表', true),
('max_file_size', '10485760', 'number', '最大文件大小(字节)', true),
('supported_file_types', '["pdf", "doc", "docx", "txt", "rtf"]', 'json', '支持的文件类型', true)
ON CONFLICT (setting_key) DO NOTHING;
-- 13. 创建索引以提高查询性能
CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON user_profiles(email);
CREATE INDEX IF NOT EXISTS idx_user_profiles_username ON user_profiles(username);
CREATE INDEX IF NOT EXISTS idx_call_records_user_id ON call_records(user_id);
CREATE INDEX IF NOT EXISTS idx_call_records_created_at ON call_records(created_at);
CREATE INDEX IF NOT EXISTS idx_appointments_user_id ON appointments(user_id);
CREATE INDEX IF NOT EXISTS idx_appointments_date ON appointments(appointment_date);
CREATE INDEX IF NOT EXISTS idx_document_translations_user_id ON document_translations(user_id);
CREATE INDEX IF NOT EXISTS idx_payments_user_id ON payments(user_id);
CREATE INDEX IF NOT EXISTS idx_payments_status ON payments(payment_status);
-- 完成初始化
SELECT 'Database initialization completed successfully!' as status;