-- =========================================== -- iConsulting 数据库初始化脚本 -- =========================================== -- 创建扩展 CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- 创建数据库 (如果不存在) -- 注意: 此脚本在 docker-entrypoint-initdb.d 中运行时,数据库已由 POSTGRES_DB 环境变量创建 -- =========================================== -- 创建表 -- =========================================== -- 用户表 CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), type VARCHAR(20) NOT NULL DEFAULT 'ANONYMOUS', phone VARCHAR(20) UNIQUE, email VARCHAR(255) UNIQUE, password_hash VARCHAR(255), name VARCHAR(100), avatar VARCHAR(500), status VARCHAR(20) NOT NULL DEFAULT 'ACTIVE', metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_active_at TIMESTAMP WITH TIME ZONE ); CREATE INDEX idx_users_phone ON users(phone); CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_users_type ON users(type); CREATE INDEX idx_users_status ON users(status); -- 管理员表 CREATE TABLE IF NOT EXISTS admins ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), username VARCHAR(50) NOT NULL UNIQUE, password_hash VARCHAR(255) NOT NULL, name VARCHAR(100) NOT NULL, email VARCHAR(255), phone VARCHAR(20), role VARCHAR(20) NOT NULL DEFAULT 'OPERATOR', permissions JSONB DEFAULT '[]', avatar VARCHAR(500), last_login_at TIMESTAMP WITH TIME ZONE, last_login_ip VARCHAR(50), is_active BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_admins_username ON admins(username); CREATE INDEX idx_admins_role ON admins(role); -- 对话表 CREATE TABLE IF NOT EXISTS conversations ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id), title VARCHAR(500), status VARCHAR(20) NOT NULL DEFAULT 'ACTIVE', message_count INTEGER DEFAULT 0, category VARCHAR(50), is_paid BOOLEAN DEFAULT false, satisfaction_score INTEGER, summary TEXT, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, closed_at TIMESTAMP WITH TIME ZONE ); CREATE INDEX idx_conversations_user_id ON conversations(user_id); CREATE INDEX idx_conversations_status ON conversations(status); CREATE INDEX idx_conversations_category ON conversations(category); CREATE INDEX idx_conversations_created_at ON conversations(created_at); -- 消息表 CREATE TABLE IF NOT EXISTS messages ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), conversation_id UUID NOT NULL REFERENCES conversations(id) ON DELETE CASCADE, role VARCHAR(20) NOT NULL, content TEXT NOT NULL, token_count INTEGER, tool_calls JSONB, citations JSONB, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_messages_conversation_id ON messages(conversation_id); CREATE INDEX idx_messages_role ON messages(role); CREATE INDEX idx_messages_created_at ON messages(created_at); -- 知识文章表 CREATE TABLE IF NOT EXISTS knowledge_articles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), title VARCHAR(500) NOT NULL, content TEXT NOT NULL, summary TEXT, category VARCHAR(50) NOT NULL, tags JSONB DEFAULT '[]', source VARCHAR(20) NOT NULL DEFAULT 'MANUAL', source_url VARCHAR(1000), is_published BOOLEAN DEFAULT false, citation_count INTEGER DEFAULT 0, quality_score INTEGER DEFAULT 50, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, published_at TIMESTAMP WITH TIME ZONE ); CREATE INDEX idx_knowledge_articles_category ON knowledge_articles(category); CREATE INDEX idx_knowledge_articles_is_published ON knowledge_articles(is_published); CREATE INDEX idx_knowledge_articles_source ON knowledge_articles(source); -- 知识块表 (用于向量检索) CREATE TABLE IF NOT EXISTS knowledge_chunks ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), article_id UUID NOT NULL REFERENCES knowledge_articles(id) ON DELETE CASCADE, content TEXT NOT NULL, chunk_index INTEGER NOT NULL, token_count INTEGER, embedding_id VARCHAR(100), metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_knowledge_chunks_article_id ON knowledge_chunks(article_id); CREATE INDEX idx_knowledge_chunks_embedding_id ON knowledge_chunks(embedding_id); -- 经验表 CREATE TABLE IF NOT EXISTS experiences ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), experience_type VARCHAR(50) NOT NULL, content TEXT NOT NULL, scenario TEXT, confidence INTEGER NOT NULL DEFAULT 50, related_category VARCHAR(50), source_conversation_ids JSONB DEFAULT '[]', verification_status VARCHAR(20) NOT NULL DEFAULT 'PENDING', verified_by UUID REFERENCES admins(id), verified_at TIMESTAMP WITH TIME ZONE, usage_count INTEGER DEFAULT 0, positive_count INTEGER DEFAULT 0, negative_count INTEGER DEFAULT 0, is_active BOOLEAN DEFAULT true, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_experiences_type ON experiences(experience_type); CREATE INDEX idx_experiences_status ON experiences(verification_status); CREATE INDEX idx_experiences_category ON experiences(related_category); CREATE INDEX idx_experiences_is_active ON experiences(is_active); -- 支付订单表 CREATE TABLE IF NOT EXISTS payment_orders ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id), conversation_id UUID REFERENCES conversations(id), order_no VARCHAR(50) NOT NULL UNIQUE, amount DECIMAL(10, 2) NOT NULL, currency VARCHAR(10) NOT NULL DEFAULT 'CNY', payment_method VARCHAR(20) NOT NULL, status VARCHAR(20) NOT NULL DEFAULT 'PENDING', product_type VARCHAR(50) NOT NULL, product_id VARCHAR(100), product_name VARCHAR(200), description TEXT, external_order_no VARCHAR(100), paid_at TIMESTAMP WITH TIME ZONE, expired_at TIMESTAMP WITH TIME ZONE, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_payment_orders_user_id ON payment_orders(user_id); CREATE INDEX idx_payment_orders_order_no ON payment_orders(order_no); CREATE INDEX idx_payment_orders_status ON payment_orders(status); CREATE INDEX idx_payment_orders_external_order_no ON payment_orders(external_order_no); -- 账户余额表 CREATE TABLE IF NOT EXISTS user_balances ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL UNIQUE REFERENCES users(id), balance DECIMAL(10, 2) NOT NULL DEFAULT 0, total_recharged DECIMAL(10, 2) NOT NULL DEFAULT 0, total_consumed DECIMAL(10, 2) NOT NULL DEFAULT 0, free_quota INTEGER NOT NULL DEFAULT 5, version INTEGER NOT NULL DEFAULT 1, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_user_balances_user_id ON user_balances(user_id); -- 账户流水表 CREATE TABLE IF NOT EXISTS balance_transactions ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id), type VARCHAR(20) NOT NULL, amount DECIMAL(10, 2) NOT NULL, balance_before DECIMAL(10, 2) NOT NULL, balance_after DECIMAL(10, 2) NOT NULL, reference_type VARCHAR(50), reference_id UUID, description TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX idx_balance_transactions_user_id ON balance_transactions(user_id); CREATE INDEX idx_balance_transactions_type ON balance_transactions(type); CREATE INDEX idx_balance_transactions_created_at ON balance_transactions(created_at); -- =========================================== -- 初始数据 -- =========================================== -- 创建默认管理员 (密码: admin123) -- 密码哈希使用 bcrypt 生成: echo -n "admin123" | htpasswd -bnBC 10 "" - | tr -d ':\n' INSERT INTO admins (id, username, password_hash, name, role, permissions) VALUES ( uuid_generate_v4(), 'admin', '$2b$10$N9qo8uLOickgx2ZMRZoMyeIjZRGdjGj/n3.QHZWL1xOsV7.Hq5mLe', '系统管理员', 'SUPER_ADMIN', '["*"]' ) ON CONFLICT (username) DO NOTHING; -- =========================================== -- 更新触发器 -- =========================================== CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; -- 为所有表添加 updated_at 触发器 DO $$ DECLARE t text; BEGIN FOR t IN SELECT table_name FROM information_schema.columns WHERE column_name = 'updated_at' AND table_schema = 'public' LOOP EXECUTE format(' DROP TRIGGER IF EXISTS update_%I_updated_at ON %I; CREATE TRIGGER update_%I_updated_at BEFORE UPDATE ON %I FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); ', t, t, t, t); END LOOP; END; $$ LANGUAGE plpgsql; -- 完成 SELECT 'Database initialization completed!' as status;