Twilioapp-project/web-app/database-schema.sql

187 lines
9.9 KiB
MySQL
Raw Normal View History

-- 翻译服务应用数据库表结构
-- 使用 Supabase PostgreSQL 数据库
-- 1. 用户档案表
CREATE TABLE IF NOT EXISTS user_profiles (
id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
email TEXT NOT NULL,
full_name TEXT,
phone TEXT,
avatar_url TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 2. 翻译员档案表
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,
full_name TEXT NOT NULL,
email TEXT NOT NULL,
phone TEXT,
avatar_url TEXT,
languages TEXT[] NOT NULL, -- 支持的语言对
specialties TEXT[], -- 专业领域
rating DECIMAL(3,2) DEFAULT 5.00, -- 评分 (0.00-5.00)
hourly_rate DECIMAL(10,2) DEFAULT 50.00, -- 小时费率
is_active BOOLEAN DEFAULT TRUE,
bio TEXT, -- 个人简介
experience_years INTEGER DEFAULT 0,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 3. 通话记录表
CREATE TABLE IF NOT EXISTS call_records (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE SET NULL,
call_type TEXT NOT NULL CHECK (call_type IN ('voice', 'video')),
duration INTEGER NOT NULL, -- 通话时长(秒)
has_translator BOOLEAN DEFAULT FALSE,
base_rate DECIMAL(10,2) NOT NULL, -- 基础费率
translator_rate DECIMAL(10,2) DEFAULT 0, -- 翻译员费率
total_amount DECIMAL(10,2) NOT NULL, -- 总金额
status TEXT DEFAULT 'completed' CHECK (status IN ('pending', 'completed', 'cancelled')),
payment_status TEXT DEFAULT 'unpaid' CHECK (payment_status IN ('unpaid', 'paid', 'refunded')),
payment_id TEXT, -- Stripe 支付ID
twilio_call_sid TEXT, -- Twilio 通话ID
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 4. 预约表
CREATE TABLE IF NOT EXISTS appointments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE SET NULL,
appointment_date DATE NOT NULL,
appointment_time TIME NOT NULL,
service_type TEXT NOT NULL CHECK (service_type IN ('voice', 'video', 'document')),
language_pair TEXT NOT NULL, -- 语言对,如 '中文-英文'
duration INTEGER DEFAULT 60, -- 预约时长(分钟)
notes TEXT, -- 备注
status TEXT DEFAULT 'pending' CHECK (status IN ('pending', 'confirmed', 'completed', 'cancelled')),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 5. 文档翻译表
CREATE TABLE IF NOT EXISTS document_translations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
translator_id UUID REFERENCES translator_profiles(id) ON DELETE SET NULL,
original_filename TEXT NOT NULL,
original_file_url TEXT NOT NULL, -- 原文件存储URL
translated_file_url TEXT, -- 翻译后文件存储URL
source_language TEXT NOT NULL,
target_language TEXT NOT NULL,
file_size INTEGER, -- 文件大小(字节)
word_count INTEGER, -- 字数统计
status TEXT DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
estimated_completion TIMESTAMP WITH TIME ZONE,
actual_completion TIMESTAMP WITH TIME ZONE,
amount DECIMAL(10,2), -- 翻译费用
payment_status TEXT DEFAULT 'unpaid' CHECK (payment_status IN ('unpaid', 'paid', 'refunded')),
payment_id TEXT, -- Stripe 支付ID
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 6. 支付记录表
CREATE TABLE IF NOT EXISTS payments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
stripe_payment_id TEXT UNIQUE NOT NULL,
amount DECIMAL(10,2) NOT NULL,
currency TEXT DEFAULT 'cny',
status TEXT NOT NULL CHECK (status IN ('pending', 'succeeded', 'failed', 'cancelled')),
payment_method TEXT, -- 支付方式
description TEXT, -- 支付描述
metadata JSONB, -- 额外的支付信息
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 7. 系统设置表
CREATE TABLE IF NOT EXISTS system_settings (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
key TEXT UNIQUE NOT NULL,
value JSONB NOT NULL,
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- 创建索引以提高查询性能
CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON user_profiles(email);
CREATE INDEX IF NOT EXISTS idx_translator_profiles_languages ON translator_profiles USING GIN(languages);
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_stripe_id ON payments(stripe_payment_id);
-- 创建更新时间触发器函数
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- 为所有表添加更新时间触发器
CREATE TRIGGER update_user_profiles_updated_at BEFORE UPDATE ON user_profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_translator_profiles_updated_at BEFORE UPDATE ON translator_profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_call_records_updated_at BEFORE UPDATE ON call_records FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_appointments_updated_at BEFORE UPDATE ON appointments FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_document_translations_updated_at BEFORE UPDATE ON document_translations FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_payments_updated_at BEFORE UPDATE ON payments FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_system_settings_updated_at BEFORE UPDATE ON system_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- 插入默认系统设置
INSERT INTO system_settings (key, value, description) VALUES
('call_rates', '{"voice": 80, "video": 120, "translator": 50}', '通话费率设置(元/小时)'),
('supported_languages', '["中文", "英文", "日文", "韩文", "法文", "德文", "西班牙文", "俄文"]', '支持的语言列表'),
('document_formats', '["pdf", "doc", "docx", "txt", "rtf"]', '支持的文档格式'),
('max_file_size', '10485760', '最大文件上传大小(字节)')
ON CONFLICT (key) DO NOTHING;
-- 插入示例翻译员数据
INSERT INTO translator_profiles (full_name, email, phone, languages, specialties, rating, hourly_rate, bio, experience_years) VALUES
('张译文', 'zhang.yiwen@example.com', '13800138001', ARRAY['中文', '英文'], ARRAY['商务', '法律', '技术'], 4.8, 80.00, '资深英语翻译具有10年商务翻译经验', 10),
('李法兰', 'li.falan@example.com', '13800138002', ARRAY['中文', '法文'], ARRAY['法律', '文学', '艺术'], 4.9, 90.00, '法语翻译专家,巴黎大学文学硕士', 12),
('田中太郎', 'tanaka.taro@example.com', '13800138003', ARRAY['中文', '日文'], ARRAY['技术', '制造', '动漫'], 4.7, 75.00, '日语翻译,专注于技术和制造业翻译', 8),
('金智慧', 'kim.jihye@example.com', '13800138004', ARRAY['中文', '韩文'], ARRAY['娱乐', '时尚', '美容'], 4.6, 70.00, '韩语翻译,熟悉韩国文化和娱乐产业', 6)
ON CONFLICT DO NOTHING;
-- 设置行级安全策略 (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;
-- 用户只能访问自己的数据
CREATE POLICY "Users can view own profile" ON user_profiles FOR SELECT USING (auth.uid() = id);
CREATE POLICY "Users can update own profile" ON user_profiles FOR UPDATE USING (auth.uid() = id);
CREATE POLICY "Users can view own call records" ON call_records FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Users can insert own call records" ON call_records FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "Users can view own appointments" ON appointments FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Users can insert own appointments" ON appointments FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "Users can update own appointments" ON appointments FOR UPDATE USING (auth.uid() = user_id);
CREATE POLICY "Users can view own document translations" ON document_translations FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Users can insert own document translations" ON document_translations FOR INSERT WITH CHECK (auth.uid() = user_id);
CREATE POLICY "Users can view own payments" ON payments FOR SELECT USING (auth.uid() = user_id);
CREATE POLICY "Users can insert own payments" ON payments FOR INSERT WITH CHECK (auth.uid() = user_id);
-- 翻译员档案可以被所有用户查看
CREATE POLICY "Anyone can view active translators" ON translator_profiles FOR SELECT USING (is_active = true);