| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185 |
- -- 多自媒体平台账号管理系统数据库表结构
- -- MySQL 8.0+
- CREATE DATABASE IF NOT EXISTS media_manager
- CHARACTER SET utf8mb4
- COLLATE utf8mb4_unicode_ci;
- USE media_manager;
- -- 用户表(软件登录账号)
- CREATE TABLE IF NOT EXISTS users (
- id INT PRIMARY KEY AUTO_INCREMENT,
- username VARCHAR(50) UNIQUE NOT NULL,
- email VARCHAR(100) UNIQUE,
- password_hash VARCHAR(255) NOT NULL,
- avatar_url VARCHAR(500),
- nickname VARCHAR(50),
- role ENUM('admin', 'editor', 'operator') DEFAULT 'operator',
- status ENUM('active', 'disabled', 'pending') DEFAULT 'active',
- last_login_at TIMESTAMP NULL,
- last_login_ip VARCHAR(50),
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 用户 Token 表(用于 Token 失效管理)
- CREATE TABLE IF NOT EXISTS user_tokens (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- refresh_token VARCHAR(500) NOT NULL,
- device_info VARCHAR(255),
- ip_address VARCHAR(50),
- expires_at TIMESTAMP NOT NULL,
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 系统配置表
- CREATE TABLE IF NOT EXISTS system_config (
- id INT PRIMARY KEY AUTO_INCREMENT,
- config_key VARCHAR(100) UNIQUE NOT NULL,
- config_value TEXT,
- description VARCHAR(255),
- updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 初始化系统配置
- INSERT INTO system_config (config_key, config_value, description) VALUES
- ('allow_registration', 'false', '是否开放用户注册'),
- ('default_user_role', 'operator', '新注册用户默认角色')
- ON DUPLICATE KEY UPDATE config_key=config_key;
- -- 创建默认管理员账号 (密码: admin123)
- INSERT INTO users (username, email, password_hash, nickname, role, status) VALUES
- ('admin', 'admin@example.com', '$2a$10$rQnM1YFKBqr6.8t5P7H5/.8mJSYvCXsMaJ6fBVdX5xFXQV8u7sSAu', '管理员', 'admin', 'active')
- ON DUPLICATE KEY UPDATE username=username;
- -- 平台账号分组表(关联用户)
- CREATE TABLE IF NOT EXISTS account_groups (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- name VARCHAR(100) NOT NULL,
- description VARCHAR(255),
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 平台账号表(关联用户,核心数据表)
- CREATE TABLE IF NOT EXISTS platform_accounts (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- platform ENUM('douyin','kuaishou','weixin_video','xiaohongshu','bilibili','toutiao','baijiahao','qie','dayuhao') NOT NULL,
- account_name VARCHAR(100),
- account_id VARCHAR(100),
- avatar_url VARCHAR(500),
- fans_count INT DEFAULT 0,
- works_count INT DEFAULT 0,
- cookie_data TEXT,
- cookie_expire_at TIMESTAMP NULL,
- status ENUM('active','expired','disabled') DEFAULT 'active',
- proxy_config JSON,
- group_id INT,
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
- FOREIGN KEY (group_id) REFERENCES account_groups(id) ON DELETE SET NULL,
- UNIQUE KEY uk_user_platform_account (user_id, platform, account_id)
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 视频发布任务表(关联用户)
- CREATE TABLE IF NOT EXISTS publish_tasks (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- video_path VARCHAR(500),
- video_filename VARCHAR(255),
- title VARCHAR(200),
- description TEXT,
- cover_path VARCHAR(500),
- tags JSON,
- target_accounts JSON,
- platform_configs JSON,
- status ENUM('pending','processing','completed','failed','cancelled') DEFAULT 'pending',
- scheduled_at TIMESTAMP NULL,
- published_at TIMESTAMP NULL,
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 发布结果表
- CREATE TABLE IF NOT EXISTS publish_results (
- id INT PRIMARY KEY AUTO_INCREMENT,
- task_id INT NOT NULL,
- account_id INT NOT NULL,
- platform VARCHAR(50),
- status ENUM('success','failed'),
- video_url VARCHAR(500),
- platform_video_id VARCHAR(100),
- error_message TEXT,
- published_at TIMESTAMP NULL,
- FOREIGN KEY (task_id) REFERENCES publish_tasks(id) ON DELETE CASCADE,
- FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 评论表(关联用户)
- CREATE TABLE IF NOT EXISTS comments (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- account_id INT NOT NULL,
- platform VARCHAR(50),
- video_id VARCHAR(100),
- platform_video_url VARCHAR(500),
- comment_id VARCHAR(100) UNIQUE,
- parent_comment_id VARCHAR(100),
- author_id VARCHAR(100),
- author_name VARCHAR(100),
- author_avatar VARCHAR(500),
- content TEXT,
- like_count INT DEFAULT 0,
- reply_content TEXT,
- replied_at TIMESTAMP NULL,
- is_read BOOLEAN DEFAULT FALSE,
- is_top BOOLEAN DEFAULT FALSE,
- comment_time TIMESTAMP NULL,
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
- FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
- INDEX idx_comment_user_read (user_id, is_read),
- INDEX idx_comment_account (account_id)
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 数据统计表(关联用户)
- CREATE TABLE IF NOT EXISTS analytics_data (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- account_id INT NOT NULL,
- date DATE NOT NULL,
- fans_count INT DEFAULT 0,
- fans_increase INT DEFAULT 0,
- views_count INT DEFAULT 0,
- likes_count INT DEFAULT 0,
- comments_count INT DEFAULT 0,
- shares_count INT DEFAULT 0,
- income DECIMAL(10,2) DEFAULT 0,
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
- FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
- UNIQUE KEY uk_account_date (account_id, date),
- INDEX idx_analytics_user_date (user_id, date)
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
- -- 操作日志表(审计追踪)
- CREATE TABLE IF NOT EXISTS operation_logs (
- id INT PRIMARY KEY AUTO_INCREMENT,
- user_id INT NOT NULL,
- action VARCHAR(50) NOT NULL,
- target_type VARCHAR(50),
- target_id INT,
- detail JSON,
- ip_address VARCHAR(50),
- user_agent VARCHAR(255),
- created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
- INDEX idx_log_user_time (user_id, created_at)
- ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|