bindbox-game/.trae/documents/头衔表设计方案.md
邹方成 8141a47690
Some checks failed
Build docker and publish / linux (1.24.5) (push) Failing after 39s
feat(称号系统): 新增称号管理功能与抽奖效果集成
- 新增系统称号模板与效果配置表及相关CRUD接口
- 实现用户称号分配与抽奖效果应用逻辑
- 优化抽奖接口支持用户ID参数以应用称号效果
- 新增称号管理前端页面与分配功能
- 修复Windows时区错误与JSON字段初始化问题
- 移除无用管理接口代码并更新文档说明
2025-11-16 11:37:40 +08:00

103 lines
4.0 KiB
Markdown
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

# 头衔表设计DDL含事务与字段说明
## 字段说明
* system\_titles`id``name``description``status``obtain_rules_json``scopes_json``created_at``updated_at`
* system\_title\_effects`id``title_id``effect_type``params_json``stacking_strategy``cap_value_x1000``scopes_json``sort``status``created_at`
* user\_titles`id``user_id``title_id``active``obtained_at``expires_at``source``remark``created_at`
* user\_title\_effect\_claims`id``user_id``title_id``effect_type``target_template_id``period_key``claim_count``last_claim_at``created_at`
* activity\_draw\_effects 扩展:`source_type``source_id`
## 事务化SQL先删表再新建含COMMIT
```sql
START TRANSACTION;
SET FOREIGN_KEY_CHECKS=0;
DROP TABLE IF EXISTS `system_title_effects`;
DROP TABLE IF EXISTS `user_title_effect_claims`;
DROP TABLE IF EXISTS `user_titles`;
DROP TABLE IF EXISTS `system_titles`;
CREATE TABLE `system_titles` (
`id` BIGINT PRIMARY KEY AUTO_INCREMENT,
`name` VARCHAR(64) NOT NULL,
`description` VARCHAR(255) NULL,
`status` TINYINT NOT NULL DEFAULT 1,
`obtain_rules_json` JSON NULL,
`scopes_json` JSON 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_system_titles_name` (`name`),
INDEX `idx_system_titles_status` (`status`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `system_title_effects` (
`id` BIGINT PRIMARY KEY AUTO_INCREMENT,
`title_id` BIGINT NOT NULL,
`effect_type` INT NOT NULL,
`params_json` JSON NOT NULL,
`stacking_strategy` INT NOT NULL DEFAULT 0,
`cap_value_x1000` INT NULL,
`scopes_json` JSON NULL,
`sort` INT NOT NULL DEFAULT 0,
`status` TINYINT NOT NULL DEFAULT 1,
`created_at` DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
CONSTRAINT `fk_title_effects_title` FOREIGN KEY (`title_id`) REFERENCES `system_titles`(`id`) ON DELETE CASCADE,
INDEX `idx_title_effects_title` (`title_id`),
INDEX `idx_title_effects_type` (`effect_type`),
INDEX `idx_title_effects_status` (`status`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `user_titles` (
`id` BIGINT PRIMARY KEY AUTO_INCREMENT,
`user_id` BIGINT NOT NULL,
`title_id` BIGINT NOT NULL,
`active` TINYINT NOT NULL DEFAULT 1,
`obtained_at` DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
`expires_at` DATETIME(3) NULL,
`source` VARCHAR(64) NULL,
`remark` VARCHAR(255) NULL,
`created_at` DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
CONSTRAINT `fk_user_titles_title` FOREIGN KEY (`title_id`) REFERENCES `system_titles`(`id`) ON DELETE CASCADE,
UNIQUE KEY `uk_user_title_unique` (`user_id`, `title_id`),
INDEX `idx_user_titles_user` (`user_id`),
INDEX `idx_user_titles_active` (`active`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `user_title_effect_claims` (
`id` BIGINT PRIMARY KEY AUTO_INCREMENT,
`user_id` BIGINT NOT NULL,
`title_id` BIGINT NOT NULL,
`effect_type` INT NOT NULL,
`target_template_id` BIGINT NULL,
`period_key` VARCHAR(16) NOT NULL,
`claim_count` INT NOT NULL DEFAULT 0,
`last_claim_at` DATETIME(3) NULL,
`created_at` DATETIME(3) NOT NULL DEFAULT CURRENT_TIMESTAMP(3),
CONSTRAINT `fk_claims_title` FOREIGN KEY (`title_id`) REFERENCES `system_titles`(`id`) ON DELETE CASCADE,
UNIQUE KEY `uk_title_claim_period` (`user_id`, `title_id`, `effect_type`, `target_template_id`, `period_key`),
INDEX `idx_title_claims_user` (`user_id`),
INDEX `idx_title_claims_effect` (`effect_type`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
ALTER TABLE `activity_draw_effects`
ADD COLUMN `source_type` INT NOT NULL DEFAULT 0,
ADD COLUMN `source_id` BIGINT NULL,
ADD INDEX `idx_draw_effects_source` (`source_type`, `source_id`);
SET FOREIGN_KEY_CHECKS=1;
COMMIT;
```
## 说明
* `period_key`:按策略生成(如每日`YYYYMMDD`、每周`YYYYWW`、每月`YYYYMM`)。
* 事务与外键检查切换保障迁移原子性与顺序删除/创建。