-- ============================================================================= -- 上号系统 - 数据库结构 (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) 管理员(平台侧) -- ----------------------------------------------------------------------------- CREATE TABLE IF NOT EXISTS admin_user ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, username VARCHAR(64) NOT NULL UNIQUE, password_hash VARBINARY(100) NOT NULL, -- 建议存储 bcrypt/argon2 等 role ENUM('SUPER','ADMIN') NOT NULL DEFAULT 'ADMIN', status ENUM('ENABLED','DISABLED') NOT NULL DEFAULT 'ENABLED', 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; -- ----------------------------------------------------------------------------- -- 2) 代理商(商家) -- ----------------------------------------------------------------------------- CREATE TABLE IF NOT EXISTS agent ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, name VARCHAR(100) NOT NULL, login_account VARCHAR(64) NOT NULL UNIQUE, password_hash VARBINARY(100) NOT NULL, status ENUM('ENABLED','DISABLED') NOT NULL DEFAULT 'ENABLED', points_balance BIGINT UNSIGNED NOT NULL DEFAULT 0, -- 当前可用点数 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_agent_points_nonneg CHECK (points_balance >= 0) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ----------------------------------------------------------------------------- -- 3) 代理商点数流水 -- 记录加点/扣点(生成链接时扣 Times×Quantity×BatchSize) -- ----------------------------------------------------------------------------- CREATE TABLE IF NOT EXISTS agent_points_tx ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, agent_id BIGINT UNSIGNED NOT NULL, 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, -- 操作者(管理员) created_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3), INDEX idx_agent_points_tx_agent_time (agent_id, created_at), CONSTRAINT fk_apx_agent FOREIGN KEY (agent_id) REFERENCES agent(id), CONSTRAINT fk_apx_operator FOREIGN KEY (operator_id) REFERENCES admin_user(id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ----------------------------------------------------------------------------- -- 4) 链接批次(一次生成 N 个链接,按统一设置扣费) -- ----------------------------------------------------------------------------- CREATE TABLE IF NOT EXISTS link_batch ( id BIGINT UNSIGNED PRIMARY KEY AUTO_INCREMENT, agent_id BIGINT UNSIGNED NOT NULL, 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 agent(id), CONSTRAINT fk_lb_operator FOREIGN KEY (operator_id) REFERENCES admin_user(id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ----------------------------------------------------------------------------- -- 5) 单链接任务(用户访问的“加密链接”对应的实体) -- ----------------------------------------------------------------------------- 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, 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 agent(id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ----------------------------------------------------------------------------- -- 6) 操作日志(审计/可观测性) -- ----------------------------------------------------------------------------- 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; -- ----------------------------------------------------------------------------- -- 7) 公告 -- ----------------------------------------------------------------------------- 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), INDEX idx_announce_enabled (enabled) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- ----------------------------------------------------------------------------- -- 8) 平台级配置(商家不可配) -- ----------------------------------------------------------------------------- CREATE TABLE IF NOT EXISTS sys_config ( cfg_key VARCHAR(64) PRIMARY KEY, cfg_value TEXT NOT NULL, description VARCHAR(255) NULL, updated_at DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3) ON UPDATE CURRENT_TIMESTAMP(3) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- 预置关键配置(可按需改值) INSERT INTO sys_config (cfg_key, cfg_value, description) VALUES ('LINK_EXPIRE_HOURS', '24', '链接有效期(小时)'), ('QR_EXPIRE_SECONDS', '60', '二维码过期秒数(脚本端未返回TTL时使用)'), ('REFRESH_WAIT_SECONDS', '10', '刷新后强制等待秒数(商家不可配置)'), ('MACHINE_COOLDOWN_MINUTES','10', '同一机器复用冷却时长(分钟)'), ('DEFAULT_BATCH_SIZE', '10', '批量生成默认数量'), ('SECOND_SCREEN_URL_TEMPLATE','https://你的域名/{codeNo}','二界面URL模板(包含编号占位)') ON DUPLICATE KEY UPDATE cfg_value = VALUES(cfg_value), description = VALUES(description); -- ----------------------------------------------------------------------------- -- 推荐的视图 / 物化统计可按需追加(此处略) -- ----------------------------------------------------------------------------- -- ============================================================================= -- 说明: -- 1) 生成链接时,请在业务层完成: -- - 计算扣点 = quantity * times * batch_size -- - 扣减 agent.points_balance,并写入 agent_points_tx -- - 写入 link_batch 及其下的若干 link_task(生成 code_no / token 及 token_hash、expire_at) -- 2) 用户端所有页面均以“加密链接 token”为入口,通过 token_hash 可实现失效/撤销。 -- 3) operation_log.detail 建议仅存必要字段并脱敏;日志保留 90 天可通过定时归档或分区处理。 -- =============================================================================