Files
sub2api/backend/migrations/016_soft_delete_partial_unique_indexes.sql
yangjianbo 59269dc1c1 fix(数据层): 修复软删除与唯一约束冲突问题
问题:软删除的记录仍占用唯一约束位置,导致删后无法重建同名/同邮箱/同订阅

修复方案:使用 PostgreSQL 部分唯一索引(WHERE deleted_at IS NULL)
- User.email: 移除字段级 Unique(),改用部分唯一索引
- Group.name: 移除字段级 Unique(),改用部分唯一索引
- UserSubscription.(user_id, group_id): 移除组合唯一索引,改用部分唯一索引
- ApiKey.key: 保留普通唯一约束(安全考虑,已删除的 Key 不应重用)

安全性:
- 应用层已有 ExistsByXxx 检查,自动过滤软删除记录
- 数据库层部分唯一索引提供最后一道防线

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2025-12-31 16:37:18 +08:00

52 lines
2.2 KiB
SQL
Raw Permalink 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.

-- 016_soft_delete_partial_unique_indexes.sql
-- 修复软删除 + 唯一约束冲突问题
-- 将普通唯一约束替换为部分唯一索引WHERE deleted_at IS NULL
-- 这样软删除的记录不会占用唯一约束位置,允许删后重建同名/同邮箱/同订阅关系
-- ============================================================================
-- 1. users 表: email 字段
-- ============================================================================
-- 删除旧的唯一约束(可能的命名方式)
ALTER TABLE users DROP CONSTRAINT IF EXISTS users_email_key;
DROP INDEX IF EXISTS users_email_key;
DROP INDEX IF EXISTS user_email_key;
-- 创建部分唯一索引:只对未删除的记录建立唯一约束
CREATE UNIQUE INDEX IF NOT EXISTS users_email_unique_active
ON users(email)
WHERE deleted_at IS NULL;
-- ============================================================================
-- 2. groups 表: name 字段
-- ============================================================================
-- 删除旧的唯一约束
ALTER TABLE groups DROP CONSTRAINT IF EXISTS groups_name_key;
DROP INDEX IF EXISTS groups_name_key;
DROP INDEX IF EXISTS group_name_key;
-- 创建部分唯一索引
CREATE UNIQUE INDEX IF NOT EXISTS groups_name_unique_active
ON groups(name)
WHERE deleted_at IS NULL;
-- ============================================================================
-- 3. user_subscriptions 表: (user_id, group_id) 组合字段
-- ============================================================================
-- 删除旧的唯一约束/索引
ALTER TABLE user_subscriptions DROP CONSTRAINT IF EXISTS user_subscriptions_user_id_group_id_key;
DROP INDEX IF EXISTS user_subscriptions_user_id_group_id_key;
DROP INDEX IF EXISTS usersubscription_user_id_group_id;
-- 创建部分唯一索引
CREATE UNIQUE INDEX IF NOT EXISTS user_subscriptions_user_group_unique_active
ON user_subscriptions(user_id, group_id)
WHERE deleted_at IS NULL;
-- ============================================================================
-- 注意: api_keys 表的 key 字段保留普通唯一约束
-- API Key 即使软删除后也不应该重复使用(安全考虑)
-- ============================================================================