134 lines
7.9 KiB
SQL
134 lines
7.9 KiB
SQL
-- =============================================================================
|
||
-- 上号系统 - 数据库结构 (MySQL 8+)
|
||
-- =============================================================================
|
||
|
||
-- 可选:创建并使用独立库
|
||
CREATE DATABASE IF NOT EXISTS login_task_db
|
||
DEFAULT CHARACTER SET utf8mb4
|
||
DEFAULT COLLATE utf8mb4_0900_ai_ci;
|
||
USE login_task_db;
|
||
|
||
SET NAMES utf8mb4;
|
||
SET sql_mode = 'STRICT_ALL_TABLES,NO_ZERO_DATE,NO_ZERO_IN_DATE,ERROR_FOR_DIVISION_BY_ZERO';
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 1) 统一账户表(管理员/代理商共用)
|
||
-- 用 user_type 区分:ADMIN | AGENT
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS user_account (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
user_type ENUM('ADMIN','AGENT') NOT NULL,
|
||
username VARCHAR(64) NOT NULL UNIQUE, -- 登录名(两类共用)
|
||
display_name VARCHAR(100) NULL, -- 展示名(AGENT 可用)
|
||
password_hash VARCHAR(120) NOT NULL, -- 建议存储 BCrypt(或临时 PLAIN:<pwd> 便于初始化)
|
||
role ENUM('SUPER','ADMIN') NULL, -- 仅 ADMIN 使用
|
||
status ENUM('ENABLED','DISABLED') NOT NULL DEFAULT 'ENABLED',
|
||
points_balance BIGINT UNSIGNED NOT NULL DEFAULT 0, -- 仅 AGENT 使用
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
updated_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3),
|
||
CONSTRAINT chk_points_nonneg CHECK (points_balance >= 0)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|
||
-- 默认管理员账号(密码:admin7uqweh12)。
|
||
-- 生产环境请尽快替换为 BCrypt 哈希;此处为 PLAIN 方便首次初始化。
|
||
INSERT INTO user_account(user_type, username, display_name, password_hash, role, status, points_balance)
|
||
VALUES ('ADMIN', 'admin', 'Super Admin', 'PLAIN:admin7uqweh12', 'SUPER', 'ENABLED', 0)
|
||
ON DUPLICATE KEY UPDATE username = username;
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 2) 代理商点数流水
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS agent_points_tx (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
account_id BIGINT UNSIGNED NOT NULL, -- 指向 user_account(AGENT)
|
||
type ENUM('ADD','DEDUCT') NOT NULL,
|
||
before_points BIGINT UNSIGNED NOT NULL,
|
||
delta_points BIGINT SIGNED NOT NULL, -- 可为正/负;与 type 对应
|
||
after_points BIGINT UNSIGNED NOT NULL,
|
||
reason ENUM('create_links','manual','refund_no_rollback','other') NOT NULL DEFAULT 'other',
|
||
ref_id BIGINT UNSIGNED NULL, -- 可关联到 link_batch.id
|
||
operator_id BIGINT UNSIGNED NULL, -- 操作者(管理员,指向 user_account)
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
INDEX idx_apx_account_time (account_id, created_at),
|
||
CONSTRAINT fk_apx_account FOREIGN KEY (account_id) REFERENCES user_account(id),
|
||
CONSTRAINT fk_apx_operator FOREIGN KEY (operator_id) REFERENCES user_account(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 3) 链接批次(一次生成 N 个链接,按统一设置扣费)
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS link_batch (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
agent_id BIGINT UNSIGNED NOT NULL, -- 指向 user_account(AGENT)
|
||
quantity INT UNSIGNED NOT NULL, -- 每次奖励数量(如 50)
|
||
times INT UNSIGNED NOT NULL, -- 重复执行次数(如 20)
|
||
batch_size INT UNSIGNED NOT NULL, -- 本批生成链接数量(如 10)
|
||
deduct_points BIGINT UNSIGNED NOT NULL, -- 扣点=quantity*times*batch_size
|
||
operator_id BIGINT UNSIGNED NULL, -- 操作者(管理员)
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
INDEX idx_lb_agent_time (agent_id, created_at),
|
||
CONSTRAINT chk_lb_quantity_pos CHECK (quantity > 0),
|
||
CONSTRAINT chk_lb_times_pos CHECK (times > 0),
|
||
CONSTRAINT chk_lb_batch_pos CHECK (batch_size > 0),
|
||
CONSTRAINT fk_lb_agent FOREIGN KEY (agent_id) REFERENCES user_account(id),
|
||
CONSTRAINT fk_lb_operator FOREIGN KEY (operator_id) REFERENCES user_account(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 4) 单链接任务(用户访问的“加密链接”对应的实体)
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS link_task (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
batch_id BIGINT UNSIGNED NOT NULL,
|
||
agent_id BIGINT UNSIGNED NOT NULL, -- 指向 user_account(AGENT)
|
||
code_no VARCHAR(32) NOT NULL, -- 后端生成的全局唯一编号
|
||
token_hash CHAR(64) NOT NULL, -- 加密token的SHA-256(用于失效/撤销)
|
||
expire_at DATETIME(3) NOT NULL, -- 链接有效期(默认 24h)
|
||
status ENUM('NEW','USING','LOGGED_IN','REFUNDED','EXPIRED') NOT NULL DEFAULT 'NEW',
|
||
region ENUM('Q','V') NULL, -- 选区;未选择前为 NULL
|
||
machine_id VARCHAR(64) NULL, -- 绑定的脚本端机器编号
|
||
login_at DATETIME(3) NULL,
|
||
refund_at DATETIME(3) NULL,
|
||
revoked_at DATETIME(3) NULL, -- 主动撤销(如需要立即失效)
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
updated_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3),
|
||
UNIQUE KEY uk_code_no (code_no),
|
||
UNIQUE KEY uk_token_hash (token_hash),
|
||
INDEX idx_agent_status (agent_id, status),
|
||
INDEX idx_expire_at (expire_at),
|
||
INDEX idx_created_at (created_at),
|
||
CONSTRAINT fk_lt_batch FOREIGN KEY (batch_id) REFERENCES link_batch(id),
|
||
CONSTRAINT fk_lt_agent FOREIGN KEY (agent_id) REFERENCES user_account(id)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 5) 操作日志(审计/可观测性)
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS operation_log (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
actor_type ENUM('admin','agent','system','user') NOT NULL,
|
||
actor_id BIGINT UNSIGNED NULL, -- 不强制外键,避免多态复杂度
|
||
code_no VARCHAR(32) NULL,
|
||
op VARCHAR(64) NOT NULL, -- 如:create_links / refund / select_region / create_qr / poll_login / release_machine
|
||
detail JSON NULL, -- 具体参数/返回(注意脱敏)
|
||
client_ip VARCHAR(45) NULL,
|
||
user_agent VARCHAR(255) NULL,
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
INDEX idx_log_code_time (code_no, created_at),
|
||
INDEX idx_log_time (created_at)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|
||
-- -----------------------------------------------------------------------------
|
||
-- 6) 公告
|
||
-- -----------------------------------------------------------------------------
|
||
CREATE TABLE IF NOT EXISTS announcement (
|
||
id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT,
|
||
title VARCHAR(100) NOT NULL,
|
||
content TEXT NOT NULL, -- 富文本
|
||
enabled TINYINT(1) NOT NULL DEFAULT 1,
|
||
jump_url VARCHAR(255) NULL,
|
||
created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
|
||
updated_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
||
|