新增钱包、换卡、标签系统的数据模型和规范

本次提交完成 add-wallet-transfer-tag-models 提案的实施和归档:

## 新增功能模块
- 钱包系统:用户/代理钱包管理,支持充值、扣款、退款、乐观锁防并发
- 换卡记录:物联卡更换历史追溯,包含套餐快照(JSONB)
- 标签系统:设备/IoT卡/号卡的统一标签管理
- 运营商渠道:四大运营商(CMCC/CUCC/CTCC/CBN)的渠道管理

## 数据库变更
- 新增 6 张表:tb_wallet, tb_wallet_transaction, tb_recharge_record, tb_card_replacement_record, tb_tag, tb_resource_tag
- 修改 2 张表:tb_carrier(新增渠道字段), tb_order(新增混合支付字段)
- 迁移版本:v6 → v7(执行时间 282.5ms)

## 代码变更
- 新增 8 个 Go 模型(符合统一规范:gorm.Model + BaseModel)
- 新增 40+ 个常量定义(含完整中文注释)
- 新增 7 个 Redis Key 生成函数
- 修复模型规范:移除重复字段,统一使用 gorm.Model 嵌入

## 文档变更
- 新增 3 个业务文档:数据模型设计、字段说明、迁移验证报告
- 更新 AGENTS.md:新增 Model 模型规范和常量注释规范
- 新增 4 个 OpenSpec 规范:wallet, carrier, card-replacement, tag
- 更新 1 个 OpenSpec 规范:iot-order(支持混合支付)

## 验证通过
-  LSP 诊断:所有模型和常量文件无错误
-  OpenSpec 验证:openspec validate --strict 通过
-  迁移执行:表结构创建成功,索引正确
-  提案归档:2026-01-13-add-wallet-transfer-tag-models

变更文件统计:29 个文件,新增 3682 行
This commit is contained in:
2026-01-13 15:47:32 +08:00
parent 2150fb6ab9
commit 6e2dc325d7
29 changed files with 3682 additions and 87 deletions

View File

@@ -0,0 +1,50 @@
-- Rollback: Remove wallet, card replacement, tag tables and revert carrier, order changes
-- Created: 2026-01-13
-- Revert order table changes
ALTER TABLE tb_order DROP COLUMN IF EXISTS online_payment_amount;
ALTER TABLE tb_order DROP COLUMN IF EXISTS wallet_payment_amount;
-- Revert carrier table changes
DROP INDEX IF EXISTS idx_carrier_type_channel;
ALTER TABLE tb_carrier DROP COLUMN IF EXISTS channel_code;
ALTER TABLE tb_carrier DROP COLUMN IF EXISTS channel_name;
ALTER TABLE tb_carrier DROP COLUMN IF EXISTS carrier_type;
-- Drop tag tables
DROP INDEX IF EXISTS idx_resource_tag_unique;
DROP INDEX IF EXISTS idx_resource_tag_composite;
DROP INDEX IF EXISTS idx_resource_tag_tag;
DROP INDEX IF EXISTS idx_resource_tag_resource;
DROP TABLE IF EXISTS tb_resource_tag;
DROP INDEX IF EXISTS idx_tag_name;
DROP INDEX IF EXISTS idx_tag_usage;
DROP TABLE IF EXISTS tb_tag;
-- Drop card replacement table
DROP INDEX IF EXISTS idx_card_replacement_no;
DROP INDEX IF EXISTS idx_card_replacement_status;
DROP INDEX IF EXISTS idx_card_replacement_new_owner;
DROP INDEX IF EXISTS idx_card_replacement_old_owner;
DROP INDEX IF EXISTS idx_card_replacement_new_card;
DROP INDEX IF EXISTS idx_card_replacement_old_card;
DROP TABLE IF EXISTS tb_card_replacement_record;
-- Drop recharge record table
DROP INDEX IF EXISTS idx_recharge_no;
DROP INDEX IF EXISTS idx_recharge_status;
DROP INDEX IF EXISTS idx_recharge_user;
DROP TABLE IF EXISTS tb_recharge_record;
-- Drop wallet transaction table
DROP INDEX IF EXISTS idx_wallet_tx_ref;
DROP INDEX IF EXISTS idx_wallet_tx_user;
DROP INDEX IF EXISTS idx_wallet_tx_wallet;
DROP TABLE IF EXISTS tb_wallet_transaction;
-- Drop wallet table
DROP INDEX IF EXISTS idx_wallet_user_type_currency;
DROP INDEX IF EXISTS idx_wallet_status;
DROP INDEX IF EXISTS idx_wallet_user;
DROP TABLE IF EXISTS tb_wallet;

View File

@@ -0,0 +1,285 @@
-- Migration: Add wallet, card replacement, tag tables and modify carrier, order tables
-- Created: 2026-01-13
-- =====================================================
-- 1. 钱包系统3 张表)
-- =====================================================
-- 1.1 钱包表
CREATE TABLE IF NOT EXISTS tb_wallet (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL,
wallet_type VARCHAR(20) NOT NULL,
balance BIGINT NOT NULL DEFAULT 0,
frozen_balance BIGINT NOT NULL DEFAULT 0,
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
status INT NOT NULL DEFAULT 1,
version INT NOT NULL DEFAULT 0,
creator BIGINT,
updater BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_wallet IS '钱包表';
COMMENT ON COLUMN tb_wallet.id IS '钱包ID';
COMMENT ON COLUMN tb_wallet.user_id IS '用户ID关联tb_account.id';
COMMENT ON COLUMN tb_wallet.wallet_type IS '钱包类型user-用户钱包, agent-代理钱包';
COMMENT ON COLUMN tb_wallet.balance IS '余额(分)';
COMMENT ON COLUMN tb_wallet.frozen_balance IS '冻结余额(分)';
COMMENT ON COLUMN tb_wallet.currency IS '币种';
COMMENT ON COLUMN tb_wallet.status IS '钱包状态1-正常 2-冻结 3-关闭';
COMMENT ON COLUMN tb_wallet.version IS '版本号(乐观锁)';
COMMENT ON COLUMN tb_wallet.creator IS '创建人ID';
COMMENT ON COLUMN tb_wallet.updater IS '更新人ID';
COMMENT ON COLUMN tb_wallet.created_at IS '创建时间';
COMMENT ON COLUMN tb_wallet.updated_at IS '更新时间';
COMMENT ON COLUMN tb_wallet.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_wallet_user ON tb_wallet(user_id, deleted_at);
CREATE INDEX idx_wallet_status ON tb_wallet(status, deleted_at);
CREATE UNIQUE INDEX idx_wallet_user_type_currency ON tb_wallet(user_id, wallet_type, currency) WHERE deleted_at IS NULL;
-- 1.2 钱包明细表
CREATE TABLE IF NOT EXISTS tb_wallet_transaction (
id BIGSERIAL PRIMARY KEY,
wallet_id BIGINT NOT NULL,
user_id BIGINT NOT NULL,
transaction_type VARCHAR(20) NOT NULL,
amount BIGINT NOT NULL,
balance_before BIGINT NOT NULL,
balance_after BIGINT NOT NULL,
status INT NOT NULL DEFAULT 1,
reference_type VARCHAR(50),
reference_id BIGINT,
remark TEXT,
metadata JSONB,
creator BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_wallet_transaction IS '钱包明细表';
COMMENT ON COLUMN tb_wallet_transaction.id IS '明细ID';
COMMENT ON COLUMN tb_wallet_transaction.wallet_id IS '钱包ID关联tb_wallet.id';
COMMENT ON COLUMN tb_wallet_transaction.user_id IS '用户ID关联tb_account.id';
COMMENT ON COLUMN tb_wallet_transaction.transaction_type IS '交易类型recharge-充值, deduct-扣款, refund-退款, commission-分佣, withdrawal-提现';
COMMENT ON COLUMN tb_wallet_transaction.amount IS '变动金额(分),正数为增加,负数为减少';
COMMENT ON COLUMN tb_wallet_transaction.balance_before IS '变动前余额(分)';
COMMENT ON COLUMN tb_wallet_transaction.balance_after IS '变动后余额(分)';
COMMENT ON COLUMN tb_wallet_transaction.status IS '交易状态1-成功 2-失败 3-处理中';
COMMENT ON COLUMN tb_wallet_transaction.reference_type IS '关联业务类型order, commission, withdrawal, topup';
COMMENT ON COLUMN tb_wallet_transaction.reference_id IS '关联业务ID';
COMMENT ON COLUMN tb_wallet_transaction.remark IS '备注';
COMMENT ON COLUMN tb_wallet_transaction.metadata IS '扩展信息JSON';
COMMENT ON COLUMN tb_wallet_transaction.creator IS '创建人ID';
COMMENT ON COLUMN tb_wallet_transaction.created_at IS '创建时间';
COMMENT ON COLUMN tb_wallet_transaction.updated_at IS '更新时间';
COMMENT ON COLUMN tb_wallet_transaction.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_wallet_tx_wallet ON tb_wallet_transaction(wallet_id, created_at DESC);
CREATE INDEX idx_wallet_tx_user ON tb_wallet_transaction(user_id, created_at DESC);
CREATE INDEX idx_wallet_tx_ref ON tb_wallet_transaction(reference_type, reference_id);
-- 1.3 充值记录表
CREATE TABLE IF NOT EXISTS tb_recharge_record (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL,
wallet_id BIGINT NOT NULL,
recharge_no VARCHAR(50) NOT NULL,
amount BIGINT NOT NULL,
payment_method VARCHAR(20) NOT NULL,
payment_channel VARCHAR(50),
payment_transaction_id VARCHAR(100),
status INT NOT NULL DEFAULT 1,
paid_at TIMESTAMP,
completed_at TIMESTAMP,
creator BIGINT,
updater BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_recharge_record IS '充值记录表';
COMMENT ON COLUMN tb_recharge_record.id IS '充值记录ID';
COMMENT ON COLUMN tb_recharge_record.user_id IS '用户ID关联tb_account.id';
COMMENT ON COLUMN tb_recharge_record.wallet_id IS '钱包ID关联tb_wallet.id';
COMMENT ON COLUMN tb_recharge_record.recharge_no IS '充值订单号(唯一)';
COMMENT ON COLUMN tb_recharge_record.amount IS '充值金额(分)';
COMMENT ON COLUMN tb_recharge_record.payment_method IS '支付方式alipay-支付宝, wechat-微信, bank-银行转账, offline-线下';
COMMENT ON COLUMN tb_recharge_record.payment_channel IS '支付渠道';
COMMENT ON COLUMN tb_recharge_record.payment_transaction_id IS '第三方支付交易号';
COMMENT ON COLUMN tb_recharge_record.status IS '充值状态1-待支付 2-已支付 3-已完成 4-已关闭 5-已退款';
COMMENT ON COLUMN tb_recharge_record.paid_at IS '支付时间';
COMMENT ON COLUMN tb_recharge_record.completed_at IS '完成时间';
COMMENT ON COLUMN tb_recharge_record.creator IS '创建人ID';
COMMENT ON COLUMN tb_recharge_record.updater IS '更新人ID';
COMMENT ON COLUMN tb_recharge_record.created_at IS '创建时间';
COMMENT ON COLUMN tb_recharge_record.updated_at IS '更新时间';
COMMENT ON COLUMN tb_recharge_record.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_recharge_user ON tb_recharge_record(user_id, created_at DESC);
CREATE INDEX idx_recharge_status ON tb_recharge_record(status, created_at DESC);
CREATE UNIQUE INDEX idx_recharge_no ON tb_recharge_record(recharge_no) WHERE deleted_at IS NULL;
-- =====================================================
-- 2. 换卡系统1 张表)
-- =====================================================
CREATE TABLE IF NOT EXISTS tb_card_replacement_record (
id BIGSERIAL PRIMARY KEY,
replacement_no VARCHAR(50) NOT NULL,
old_card_id BIGINT NOT NULL,
old_iccid VARCHAR(50) NOT NULL,
new_card_id BIGINT NOT NULL,
new_iccid VARCHAR(50) NOT NULL,
old_owner_type VARCHAR(20) NOT NULL,
old_owner_id BIGINT NOT NULL,
old_agent_id BIGINT,
new_owner_type VARCHAR(20) NOT NULL,
new_owner_id BIGINT NOT NULL,
new_agent_id BIGINT,
package_snapshot JSONB,
replacement_reason VARCHAR(20) NOT NULL,
remark TEXT,
status INT NOT NULL DEFAULT 1,
approved_by BIGINT,
approved_at TIMESTAMP,
completed_at TIMESTAMP,
creator BIGINT,
updater BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_card_replacement_record IS '换卡记录表';
COMMENT ON COLUMN tb_card_replacement_record.id IS '换卡记录ID';
COMMENT ON COLUMN tb_card_replacement_record.replacement_no IS '换卡单号(唯一)';
COMMENT ON COLUMN tb_card_replacement_record.old_card_id IS '老卡ID关联tb_iot_card.id';
COMMENT ON COLUMN tb_card_replacement_record.old_iccid IS '老卡ICCID冗余存储';
COMMENT ON COLUMN tb_card_replacement_record.new_card_id IS '新卡ID关联tb_iot_card.id';
COMMENT ON COLUMN tb_card_replacement_record.new_iccid IS '新卡ICCID冗余存储';
COMMENT ON COLUMN tb_card_replacement_record.old_owner_type IS '老卡所有者类型';
COMMENT ON COLUMN tb_card_replacement_record.old_owner_id IS '老卡所有者ID';
COMMENT ON COLUMN tb_card_replacement_record.old_agent_id IS '老卡代理ID';
COMMENT ON COLUMN tb_card_replacement_record.new_owner_type IS '新卡所有者类型';
COMMENT ON COLUMN tb_card_replacement_record.new_owner_id IS '新卡所有者ID';
COMMENT ON COLUMN tb_card_replacement_record.new_agent_id IS '新卡代理ID';
COMMENT ON COLUMN tb_card_replacement_record.package_snapshot IS '套餐快照JSON';
COMMENT ON COLUMN tb_card_replacement_record.replacement_reason IS '换卡原因damaged-损坏, lost-丢失, malfunction-故障, upgrade-升级, other-其他';
COMMENT ON COLUMN tb_card_replacement_record.remark IS '备注';
COMMENT ON COLUMN tb_card_replacement_record.status IS '换卡状态1-待审批 2-已通过 3-已拒绝 4-已完成';
COMMENT ON COLUMN tb_card_replacement_record.approved_by IS '审批人ID';
COMMENT ON COLUMN tb_card_replacement_record.approved_at IS '审批时间';
COMMENT ON COLUMN tb_card_replacement_record.completed_at IS '完成时间';
COMMENT ON COLUMN tb_card_replacement_record.creator IS '创建人ID';
COMMENT ON COLUMN tb_card_replacement_record.updater IS '更新人ID';
COMMENT ON COLUMN tb_card_replacement_record.created_at IS '创建时间';
COMMENT ON COLUMN tb_card_replacement_record.updated_at IS '更新时间';
COMMENT ON COLUMN tb_card_replacement_record.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_card_replacement_old_card ON tb_card_replacement_record(old_card_id, created_at DESC);
CREATE INDEX idx_card_replacement_new_card ON tb_card_replacement_record(new_card_id, created_at DESC);
CREATE INDEX idx_card_replacement_old_owner ON tb_card_replacement_record(old_owner_type, old_owner_id);
CREATE INDEX idx_card_replacement_new_owner ON tb_card_replacement_record(new_owner_type, new_owner_id);
CREATE INDEX idx_card_replacement_status ON tb_card_replacement_record(status, created_at DESC);
CREATE UNIQUE INDEX idx_card_replacement_no ON tb_card_replacement_record(replacement_no) WHERE deleted_at IS NULL;
-- =====================================================
-- 3. 标签系统2 张表)
-- =====================================================
-- 3.1 标签表
CREATE TABLE IF NOT EXISTS tb_tag (
id BIGSERIAL PRIMARY KEY,
name VARCHAR(100) NOT NULL,
color VARCHAR(20),
usage_count INT NOT NULL DEFAULT 0,
creator BIGINT,
updater BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_tag IS '标签表';
COMMENT ON COLUMN tb_tag.id IS '标签ID';
COMMENT ON COLUMN tb_tag.name IS '标签名称(唯一)';
COMMENT ON COLUMN tb_tag.color IS '标签颜色(十六进制)';
COMMENT ON COLUMN tb_tag.usage_count IS '使用次数';
COMMENT ON COLUMN tb_tag.creator IS '创建人ID';
COMMENT ON COLUMN tb_tag.updater IS '更新人ID';
COMMENT ON COLUMN tb_tag.created_at IS '创建时间';
COMMENT ON COLUMN tb_tag.updated_at IS '更新时间';
COMMENT ON COLUMN tb_tag.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_tag_usage ON tb_tag(usage_count DESC, deleted_at);
CREATE UNIQUE INDEX idx_tag_name ON tb_tag(name) WHERE deleted_at IS NULL;
-- 3.2 资源-标签关联表
CREATE TABLE IF NOT EXISTS tb_resource_tag (
id BIGSERIAL PRIMARY KEY,
resource_type VARCHAR(20) NOT NULL,
resource_id BIGINT NOT NULL,
tag_id BIGINT NOT NULL,
creator BIGINT,
updater BIGINT,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
COMMENT ON TABLE tb_resource_tag IS '资源-标签关联表';
COMMENT ON COLUMN tb_resource_tag.id IS '关联记录ID';
COMMENT ON COLUMN tb_resource_tag.resource_type IS '资源类型device-设备, iot_card-IoT卡, number_card-号卡';
COMMENT ON COLUMN tb_resource_tag.resource_id IS '资源ID';
COMMENT ON COLUMN tb_resource_tag.tag_id IS '标签ID关联tb_tag.id';
COMMENT ON COLUMN tb_resource_tag.creator IS '创建人ID';
COMMENT ON COLUMN tb_resource_tag.updater IS '更新人ID';
COMMENT ON COLUMN tb_resource_tag.created_at IS '创建时间';
COMMENT ON COLUMN tb_resource_tag.updated_at IS '更新时间';
COMMENT ON COLUMN tb_resource_tag.deleted_at IS '删除时间(软删除)';
CREATE INDEX idx_resource_tag_resource ON tb_resource_tag(resource_type, resource_id, deleted_at);
CREATE INDEX idx_resource_tag_tag ON tb_resource_tag(tag_id, deleted_at);
CREATE INDEX idx_resource_tag_composite ON tb_resource_tag(resource_type, tag_id, deleted_at);
CREATE UNIQUE INDEX idx_resource_tag_unique ON tb_resource_tag(resource_type, resource_id, tag_id) WHERE deleted_at IS NULL;
-- =====================================================
-- 4. 修改运营商表(增加渠道字段)
-- =====================================================
ALTER TABLE tb_carrier ADD COLUMN IF NOT EXISTS carrier_type VARCHAR(20) NOT NULL DEFAULT 'CMCC';
ALTER TABLE tb_carrier ADD COLUMN IF NOT EXISTS channel_name VARCHAR(100);
ALTER TABLE tb_carrier ADD COLUMN IF NOT EXISTS channel_code VARCHAR(50);
COMMENT ON COLUMN tb_carrier.carrier_type IS '运营商类型CMCC-中国移动, CUCC-中国联通, CTCC-中国电信, CBN-广电';
COMMENT ON COLUMN tb_carrier.channel_name IS '渠道名称(可自定义)';
COMMENT ON COLUMN tb_carrier.channel_code IS '渠道编码(可自定义)';
-- 创建新的唯一索引
CREATE UNIQUE INDEX idx_carrier_type_channel ON tb_carrier(carrier_type, channel_code) WHERE deleted_at IS NULL;
-- 初始化现有数据的 carrier_type根据 carrier_code 推断)
UPDATE tb_carrier SET carrier_type = 'CMCC' WHERE carrier_code LIKE '%CMCC%' OR carrier_code LIKE '%移动%';
UPDATE tb_carrier SET carrier_type = 'CUCC' WHERE carrier_code LIKE '%CUCC%' OR carrier_code LIKE '%联通%';
UPDATE tb_carrier SET carrier_type = 'CTCC' WHERE carrier_code LIKE '%CTCC%' OR carrier_code LIKE '%电信%';
UPDATE tb_carrier SET carrier_type = 'CBN' WHERE carrier_code LIKE '%CBN%' OR carrier_code LIKE '%广电%';
-- =====================================================
-- 5. 修改订单表(增加钱包支付字段)
-- =====================================================
ALTER TABLE tb_order ADD COLUMN IF NOT EXISTS wallet_payment_amount BIGINT NOT NULL DEFAULT 0;
ALTER TABLE tb_order ADD COLUMN IF NOT EXISTS online_payment_amount BIGINT NOT NULL DEFAULT 0;
COMMENT ON COLUMN tb_order.wallet_payment_amount IS '钱包支付金额(分)';
COMMENT ON COLUMN tb_order.online_payment_amount IS '在线支付金额(分)';
-- 初始化现有订单的支付金额字段
UPDATE tb_order SET wallet_payment_amount = amount WHERE payment_method = 'wallet';
UPDATE tb_order SET online_payment_amount = amount WHERE payment_method = 'online' OR payment_method = 'carrier';