-- 口译服务管理平台数据库表结构 -- 请在Supabase SQL编辑器中执行此脚本 -- 启用必要的扩展 CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- 企业表(需要先创建,因为users表引用它) CREATE TABLE IF NOT EXISTS enterprises ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, name VARCHAR(200) NOT NULL, contact_person VARCHAR(100), contact_email VARCHAR(255), contact_phone VARCHAR(20), address TEXT, tax_number VARCHAR(50), status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 译员表(需要先创建,因为orders表引用它) CREATE TABLE IF NOT EXISTS interpreters ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, name VARCHAR(100) NOT NULL, email VARCHAR(255) UNIQUE NOT NULL, phone VARCHAR(20), languages TEXT[] NOT NULL, specialties TEXT[], status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'busy')), rating DECIMAL(3,2) DEFAULT 0 CHECK (rating >= 0 AND rating <= 5), total_calls INTEGER DEFAULT 0, hourly_rate DECIMAL(8,2), currency VARCHAR(3) NOT NULL DEFAULT 'CNY', avatar_url TEXT, bio TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 用户表 CREATE TABLE IF NOT EXISTS users ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, email VARCHAR(255) UNIQUE NOT NULL, name VARCHAR(100) NOT NULL, phone VARCHAR(20), user_type VARCHAR(20) NOT NULL DEFAULT 'individual' CHECK (user_type IN ('individual', 'enterprise', 'admin')), status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')), enterprise_id UUID REFERENCES enterprises(id), avatar_url TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 企业合同表 CREATE TABLE IF NOT EXISTS enterprise_contracts ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, enterprise_id UUID NOT NULL REFERENCES enterprises(id) ON DELETE CASCADE, contract_number VARCHAR(50) UNIQUE NOT NULL, contract_type VARCHAR(50) NOT NULL, start_date DATE NOT NULL, end_date DATE NOT NULL, total_amount DECIMAL(10,2) NOT NULL, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'expired', 'terminated')), service_rates JSONB, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 企业账单表 CREATE TABLE IF NOT EXISTS enterprise_bills ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, enterprise_id UUID NOT NULL REFERENCES enterprises(id) ON DELETE CASCADE, bill_number VARCHAR(50) UNIQUE NOT NULL, billing_period_start DATE NOT NULL, billing_period_end DATE NOT NULL, total_amount DECIMAL(10,2) NOT NULL, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'paid', 'overdue', 'cancelled')), items JSONB, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 订单表 CREATE TABLE IF NOT EXISTS orders ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, order_number VARCHAR(50) UNIQUE NOT NULL, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, user_name VARCHAR(100) NOT NULL, user_email VARCHAR(255) NOT NULL, service_type VARCHAR(50) NOT NULL, service_name VARCHAR(100) NOT NULL, source_language VARCHAR(50) NOT NULL, target_language VARCHAR(50) NOT NULL, duration INTEGER, -- 分钟 status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'confirmed', 'in_progress', 'completed', 'cancelled')), priority VARCHAR(10) NOT NULL DEFAULT 'normal' CHECK (priority IN ('low', 'normal', 'high', 'urgent')), cost DECIMAL(10,2) NOT NULL, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', scheduled_time TIMESTAMP WITH TIME ZONE, started_time TIMESTAMP WITH TIME ZONE, completed_time TIMESTAMP WITH TIME ZONE, interpreter_id UUID REFERENCES interpreters(id), interpreter_name VARCHAR(100), notes TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 发票表 CREATE TABLE IF NOT EXISTS invoices ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, invoice_number VARCHAR(50) UNIQUE NOT NULL, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, user_name VARCHAR(100) NOT NULL, user_email VARCHAR(255) NOT NULL, order_id UUID REFERENCES orders(id), invoice_type VARCHAR(20) NOT NULL CHECK (invoice_type IN ('personal', 'company')), personal_name VARCHAR(100), company_name VARCHAR(200), tax_number VARCHAR(50), company_address TEXT, subtotal DECIMAL(10,2) NOT NULL, tax_amount DECIMAL(10,2) NOT NULL DEFAULT 0, total_amount DECIMAL(10,2) NOT NULL, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'issued', 'sent', 'paid', 'cancelled')), issue_date DATE, due_date DATE, paid_date DATE, items JSONB, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 通话记录表 CREATE TABLE IF NOT EXISTS calls ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, interpreter_id UUID NOT NULL REFERENCES interpreters(id) ON DELETE CASCADE, service_type VARCHAR(50) NOT NULL, source_language VARCHAR(50) NOT NULL, target_language VARCHAR(50) NOT NULL, status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'active', 'completed', 'cancelled')), duration INTEGER DEFAULT 0, -- 秒 cost DECIMAL(10,2) DEFAULT 0, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', quality_rating INTEGER CHECK (quality_rating >= 1 AND quality_rating <= 5), started_at TIMESTAMP WITH TIME ZONE, ended_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 文档翻译表 CREATE TABLE IF NOT EXISTS documents ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, filename VARCHAR(255) NOT NULL, original_name VARCHAR(255) NOT NULL, file_size BIGINT NOT NULL, file_type VARCHAR(50) NOT NULL, source_language VARCHAR(50) NOT NULL, target_language VARCHAR(50) NOT NULL, status VARCHAR(20) NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'failed')), progress INTEGER DEFAULT 0 CHECK (progress >= 0 AND progress <= 100), cost DECIMAL(10,2) NOT NULL, currency VARCHAR(3) NOT NULL DEFAULT 'CNY', translated_file_url TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- 系统设置表 CREATE TABLE IF NOT EXISTS system_settings ( id UUID DEFAULT uuid_generate_v4() PRIMARY KEY, key VARCHAR(100) UNIQUE NOT NULL, value TEXT 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_users_email ON users(email); CREATE INDEX IF NOT EXISTS idx_users_user_type ON users(user_type); CREATE INDEX IF NOT EXISTS idx_users_enterprise_id ON users(enterprise_id); CREATE INDEX IF NOT EXISTS idx_orders_user_id ON orders(user_id); CREATE INDEX IF NOT EXISTS idx_orders_status ON orders(status); CREATE INDEX IF NOT EXISTS idx_orders_created_at ON orders(created_at); CREATE INDEX IF NOT EXISTS idx_invoices_user_id ON invoices(user_id); CREATE INDEX IF NOT EXISTS idx_invoices_order_id ON invoices(order_id); CREATE INDEX IF NOT EXISTS idx_calls_user_id ON calls(user_id); CREATE INDEX IF NOT EXISTS idx_calls_interpreter_id ON calls(interpreter_id); CREATE INDEX IF NOT EXISTS idx_documents_user_id ON documents(user_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_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_enterprises_updated_at BEFORE UPDATE ON enterprises FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_enterprise_contracts_updated_at BEFORE UPDATE ON enterprise_contracts FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_enterprise_bills_updated_at BEFORE UPDATE ON enterprise_bills FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_orders_updated_at BEFORE UPDATE ON orders FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_invoices_updated_at BEFORE UPDATE ON invoices FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_interpreters_updated_at BEFORE UPDATE ON interpreters FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_calls_updated_at BEFORE UPDATE ON calls FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_documents_updated_at BEFORE UPDATE ON documents 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(); -- 启用行级安全策略 (RLS) ALTER TABLE users ENABLE ROW LEVEL SECURITY; ALTER TABLE enterprises ENABLE ROW LEVEL SECURITY; ALTER TABLE enterprise_contracts ENABLE ROW LEVEL SECURITY; ALTER TABLE enterprise_bills ENABLE ROW LEVEL SECURITY; ALTER TABLE orders ENABLE ROW LEVEL SECURITY; ALTER TABLE invoices ENABLE ROW LEVEL SECURITY; ALTER TABLE interpreters ENABLE ROW LEVEL SECURITY; ALTER TABLE calls ENABLE ROW LEVEL SECURITY; ALTER TABLE documents ENABLE ROW LEVEL SECURITY; ALTER TABLE system_settings ENABLE ROW LEVEL SECURITY; -- 创建基本的RLS策略(管理员可以访问所有数据) CREATE POLICY "管理员可以访问所有用户数据" ON users FOR ALL USING ( EXISTS ( SELECT 1 FROM users WHERE id = auth.uid() AND user_type = 'admin' ) ); CREATE POLICY "用户可以访问自己的数据" ON users FOR ALL USING (id = auth.uid()); -- 为其他表创建类似的策略 CREATE POLICY "管理员可以访问所有企业数据" ON enterprises FOR ALL USING ( EXISTS ( SELECT 1 FROM users WHERE id = auth.uid() AND user_type = 'admin' ) ); CREATE POLICY "管理员可以访问所有订单数据" ON orders FOR ALL USING ( EXISTS ( SELECT 1 FROM users WHERE id = auth.uid() AND user_type = 'admin' ) ); CREATE POLICY "用户可以访问自己的订单" ON orders FOR ALL USING (user_id = auth.uid()); -- 插入一些系统设置 INSERT INTO system_settings (key, value, description) VALUES ('app_name', '口译服务管理平台', '应用程序名称'), ('app_version', '1.0.0', '应用程序版本'), ('maintenance_mode', 'false', '维护模式开关'), ('max_file_size', '10485760', '最大文件上传大小(字节)'), ('supported_languages', '["中文", "英文", "日文", "韩文", "法文", "德文", "西班牙文", "俄文"]', '支持的语言列表'), ('default_currency', 'CNY', '默认货币'), ('tax_rate', '0.13', '税率') ON CONFLICT (key) DO NOTHING;