feat(wallet,tag): 钱包和标签系统多租户改造

核心变更:
- 钱包表:删除 user_id,添加 resource_type/resource_id(绑定资源而非用户)
- 标签表:添加 enterprise_id/shop_id(实现三级隔离:全局/企业/店铺)
- GORM Callback:自动数据权限过滤
- 迁移脚本:可重复执行,已验证回滚功能

钱包归属重构原因:
- 旧设计:钱包绑定用户账号,个人客户卡/设备转手后新用户无法使用余额
- 新设计:钱包绑定资源(卡/设备/店铺),余额随资源流转

标签三级隔离:
- 平台全局标签:所有用户可见
- 企业标签:仅该企业可见(企业内唯一)
- 店铺标签:该店铺及下级可见(店铺内唯一)

测试覆盖:
- 9 个单元测试验证标签多租户过滤(全部通过)
- 迁移和回滚功能测试通过(测试环境)
- OpenSpec 验证通过

变更 ID: fix-wallet-tag-multi-tenant
迁移版本: 000008
参考: openspec/changes/archive/2026-01-13-fix-wallet-tag-multi-tenant/
This commit is contained in:
2026-01-13 16:52:37 +08:00
parent 6e2dc325d7
commit 2570269c8d
18 changed files with 3145 additions and 41 deletions

View File

@@ -0,0 +1,83 @@
-- ========================================
-- 钱包和标签系统多租户改造 - 回滚脚本
-- 变更 ID: fix-wallet-tag-multi-tenant
-- ========================================
-- ========================================
-- 第 1 步:恢复钱包表
-- ========================================
DROP TABLE IF EXISTS tb_wallet CASCADE;
CREATE TABLE tb_wallet AS SELECT * FROM tb_wallet_backup;
-- ========================================
-- 第 2 步:恢复标签表
-- ========================================
ALTER TABLE tb_tag DROP COLUMN IF EXISTS enterprise_id CASCADE;
ALTER TABLE tb_tag DROP COLUMN IF EXISTS shop_id CASCADE;
DROP INDEX IF EXISTS idx_tag_enterprise;
DROP INDEX IF EXISTS idx_tag_shop;
DROP INDEX IF EXISTS idx_tag_enterprise_name;
DROP INDEX IF EXISTS idx_tag_shop_name;
DROP INDEX IF EXISTS idx_tag_global_name;
CREATE UNIQUE INDEX idx_tag_name ON tb_tag (name) WHERE deleted_at IS NULL;
-- ========================================
-- 第 3 步:恢复资源标签表
-- ========================================
ALTER TABLE tb_resource_tag DROP COLUMN IF EXISTS enterprise_id CASCADE;
ALTER TABLE tb_resource_tag DROP COLUMN IF EXISTS shop_id CASCADE;
DROP INDEX IF EXISTS idx_resource_tag_enterprise;
DROP INDEX IF EXISTS idx_resource_tag_shop;
-- ========================================
-- 第 4 步:验证回滚结果
-- ========================================
DO $$
DECLARE
wallet_count INTEGER;
tag_has_enterprise BOOLEAN;
tag_has_shop BOOLEAN;
BEGIN
SELECT COUNT(*) INTO wallet_count FROM tb_wallet;
SELECT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'tb_tag' AND column_name = 'enterprise_id'
) INTO tag_has_enterprise;
SELECT EXISTS (
SELECT 1 FROM information_schema.columns
WHERE table_name = 'tb_tag' AND column_name = 'shop_id'
) INTO tag_has_shop;
RAISE NOTICE '========================================';
RAISE NOTICE '回滚验证:';
RAISE NOTICE ' 钱包记录数: %', wallet_count;
RAISE NOTICE ' 标签表 enterprise_id 字段存在: %', tag_has_enterprise;
RAISE NOTICE ' 标签表 shop_id 字段存在: %', tag_has_shop;
RAISE NOTICE '========================================';
IF tag_has_enterprise OR tag_has_shop THEN
RAISE WARNING '标签表字段未完全删除,请检查';
END IF;
END $$;
-- ========================================
-- 第 5 步:清理备份表(可选,建议手动执行)
-- ========================================
-- DROP TABLE IF EXISTS tb_wallet_backup;
-- DROP TABLE IF EXISTS tb_tag_backup;
-- DROP TABLE IF EXISTS tb_resource_tag_backup;
-- ========================================
-- 回滚完成
-- ========================================

View File

@@ -0,0 +1,220 @@
-- ========================================
-- 钱包和标签系统多租户改造 - 数据迁移脚本
-- 变更 ID: fix-wallet-tag-multi-tenant
-- ========================================
-- ========================================
-- 第 1 步:备份数据
-- ========================================
-- 删除旧备份表(如果存在)
DROP TABLE IF EXISTS tb_wallet_backup;
DROP TABLE IF EXISTS tb_tag_backup;
DROP TABLE IF EXISTS tb_resource_tag_backup;
-- 备份钱包表
CREATE TABLE tb_wallet_backup AS SELECT * FROM tb_wallet;
-- 备份标签表
CREATE TABLE tb_tag_backup AS SELECT * FROM tb_tag;
-- 备份资源标签表
CREATE TABLE tb_resource_tag_backup AS SELECT * FROM tb_resource_tag;
-- ========================================
-- 第 2 步:钱包表结构变更
-- ========================================
-- 添加新字段(先添加,允许 NULL
ALTER TABLE tb_wallet
ADD COLUMN resource_type VARCHAR(20),
ADD COLUMN resource_id BIGINT;
-- 迁移代理钱包数据
-- 代理钱包从 user_id 迁移到 shop_id
UPDATE tb_wallet w
SET
resource_type = 'shop',
resource_id = a.shop_id
FROM tb_account a
WHERE
w.user_id = a.id
AND w.wallet_type = 'agent'
AND a.shop_id IS NOT NULL;
-- 标记无法迁移的代理钱包shop_id 为 NULL
UPDATE tb_wallet
SET resource_type = 'INVALID_AGENT'
WHERE wallet_type = 'agent' AND resource_type IS NULL;
-- 标记用户钱包为待处理(需要业务人员确认)
UPDATE tb_wallet
SET
resource_type = 'PENDING_USER',
resource_id = 0
WHERE wallet_type = 'user' AND resource_type IS NULL;
-- 检查是否有无法迁移的数据
DO $$
DECLARE
invalid_count INTEGER;
pending_count INTEGER;
BEGIN
SELECT COUNT(*) INTO invalid_count FROM tb_wallet WHERE resource_type = 'INVALID_AGENT';
SELECT COUNT(*) INTO pending_count FROM tb_wallet WHERE resource_type = 'PENDING_USER';
IF invalid_count > 0 THEN
RAISE EXCEPTION '存在 % 个无法迁移的代理钱包shop_id 为 NULL请手动处理', invalid_count;
END IF;
IF pending_count > 0 THEN
RAISE NOTICE '存在 % 个待确认的用户钱包,需要业务人员确认归属', pending_count;
END IF;
END $$;
-- 设置字段为 NOT NULL
ALTER TABLE tb_wallet
ALTER COLUMN resource_type SET NOT NULL,
ALTER COLUMN resource_id SET NOT NULL;
-- 删除旧字段和约束
DROP INDEX IF EXISTS idx_wallet_user_type_currency;
DROP INDEX IF EXISTS idx_wallet_user;
ALTER TABLE tb_wallet DROP COLUMN user_id;
-- 创建新索引和约束
CREATE UNIQUE INDEX idx_wallet_resource_type_currency
ON tb_wallet (resource_type, resource_id, wallet_type, currency)
WHERE deleted_at IS NULL;
CREATE INDEX idx_wallet_resource ON tb_wallet (resource_type, resource_id, deleted_at);
-- 保留状态索引(如果不存在)
CREATE INDEX IF NOT EXISTS idx_wallet_status ON tb_wallet (status, deleted_at);
-- ========================================
-- 第 3 步:标签表结构变更
-- ========================================
-- 添加新字段
ALTER TABLE tb_tag
ADD COLUMN enterprise_id BIGINT,
ADD COLUMN shop_id BIGINT;
-- 迁移企业标签数据(从 creator 推断)
UPDATE tb_tag t
SET enterprise_id = (
SELECT a.enterprise_id
FROM tb_account a
WHERE a.id = t.creator AND a.enterprise_id IS NOT NULL
LIMIT 1
);
-- 迁移店铺标签数据(从 creator 推断)
UPDATE tb_tag t
SET shop_id = (
SELECT a.shop_id
FROM tb_account a
WHERE a.id = t.creator AND a.shop_id IS NOT NULL
LIMIT 1
)
WHERE enterprise_id IS NULL;
-- 其他标签默认为全局标签enterprise_id 和 shop_id 都为 NULL
-- 删除旧约束
DROP INDEX IF EXISTS idx_tag_name;
-- 创建新索引
CREATE INDEX idx_tag_enterprise ON tb_tag (enterprise_id, deleted_at);
CREATE INDEX idx_tag_shop ON tb_tag (shop_id, deleted_at);
-- 创建新唯一约束
CREATE UNIQUE INDEX idx_tag_enterprise_name
ON tb_tag (enterprise_id, name)
WHERE deleted_at IS NULL AND enterprise_id IS NOT NULL;
CREATE UNIQUE INDEX idx_tag_shop_name
ON tb_tag (shop_id, name)
WHERE deleted_at IS NULL AND shop_id IS NOT NULL;
CREATE UNIQUE INDEX idx_tag_global_name
ON tb_tag (name)
WHERE deleted_at IS NULL AND enterprise_id IS NULL AND shop_id IS NULL;
-- ========================================
-- 第 4 步:资源标签表结构变更
-- ========================================
-- 添加新字段
ALTER TABLE tb_resource_tag
ADD COLUMN enterprise_id BIGINT,
ADD COLUMN shop_id BIGINT;
-- 从 creator 推断归属(企业)
UPDATE tb_resource_tag rt
SET enterprise_id = (
SELECT a.enterprise_id
FROM tb_account a
WHERE a.id = rt.creator AND a.enterprise_id IS NOT NULL
LIMIT 1
);
-- 从 creator 推断归属(店铺)
UPDATE tb_resource_tag rt
SET shop_id = (
SELECT a.shop_id
FROM tb_account a
WHERE a.id = rt.creator AND a.shop_id IS NOT NULL
LIMIT 1
)
WHERE enterprise_id IS NULL;
-- 创建索引
CREATE INDEX idx_resource_tag_enterprise ON tb_resource_tag (enterprise_id, deleted_at);
CREATE INDEX idx_resource_tag_shop ON tb_resource_tag (shop_id, deleted_at);
-- ========================================
-- 第 5 步:验证数据一致性
-- ========================================
-- 输出迁移统计信息
DO $$
DECLARE
wallet_total INTEGER;
wallet_shop INTEGER;
wallet_pending INTEGER;
tag_total INTEGER;
tag_enterprise INTEGER;
tag_shop INTEGER;
tag_global INTEGER;
BEGIN
-- 钱包统计
SELECT COUNT(*) INTO wallet_total FROM tb_wallet;
SELECT COUNT(*) INTO wallet_shop FROM tb_wallet WHERE resource_type = 'shop';
SELECT COUNT(*) INTO wallet_pending FROM tb_wallet WHERE resource_type = 'PENDING_USER';
RAISE NOTICE '========================================';
RAISE NOTICE '钱包迁移统计:';
RAISE NOTICE ' 总数: %', wallet_total;
RAISE NOTICE ' 店铺钱包: %', wallet_shop;
RAISE NOTICE ' 待确认用户钱包: %', wallet_pending;
-- 标签统计
SELECT COUNT(*) INTO tag_total FROM tb_tag;
SELECT COUNT(*) INTO tag_enterprise FROM tb_tag WHERE enterprise_id IS NOT NULL;
SELECT COUNT(*) INTO tag_shop FROM tb_tag WHERE shop_id IS NOT NULL;
SELECT COUNT(*) INTO tag_global FROM tb_tag WHERE enterprise_id IS NULL AND shop_id IS NULL;
RAISE NOTICE '========================================';
RAISE NOTICE '标签迁移统计:';
RAISE NOTICE ' 总数: %', tag_total;
RAISE NOTICE ' 企业标签: %', tag_enterprise;
RAISE NOTICE ' 店铺标签: %', tag_shop;
RAISE NOTICE ' 全局标签: %', tag_global;
RAISE NOTICE '========================================';
END $$;
-- ========================================
-- 迁移完成
-- ========================================