Files
sub2api/backend/migrations/019_migrate_wechat_to_attributes.sql
huangzhenpc f2b1fc0ace
Some checks failed
CI / test (push) Has been cancelled
CI / golangci-lint (push) Has been cancelled
fix: 恢复所有迁移文件以修复校验和错误
恢复了以下迁移文件到原始状态:
- 004_add_redeem_code_notes.sql
- 005_schema_parity.sql
- 006_fix_invalid_subscription_expires_at.sql
- 007_add_user_allowed_groups.sql
- 008_seed_default_group.sql
- 009_fix_usage_logs_cache_columns.sql
- 010_add_usage_logs_aggregated_indexes.sql
- 011_remove_duplicate_unique_indexes.sql
- 012_add_user_subscription_soft_delete.sql
- 013_log_orphan_allowed_groups.sql
- 014_drop_legacy_allowed_groups.sql
- 015_fix_settings_unique_constraint.sql
- 016_soft_delete_partial_unique_indexes.sql
- 018_user_attributes.sql
- 019_migrate_wechat_to_attributes.sql
- 024_add_gemini_tier_id.sql

数据库迁移文件不应在应用后修改,即使只是注释。
2026-01-04 18:21:46 +08:00

84 lines
2.8 KiB
SQL

-- Migration: Move wechat field from users table to user_attribute_values
-- This migration:
-- 1. Creates a "wechat" attribute definition
-- 2. Migrates existing wechat data to user_attribute_values
-- 3. Does NOT drop the wechat column (for rollback safety, can be done in a later migration)
-- +goose Up
-- +goose StatementBegin
-- Step 1: Insert wechat attribute definition if not exists
INSERT INTO user_attribute_definitions (key, name, description, type, options, required, validation, placeholder, display_order, enabled, created_at, updated_at)
SELECT 'wechat', '微信', '用户微信号', 'text', '[]'::jsonb, false, '{}'::jsonb, '请输入微信号', 0, true, NOW(), NOW()
WHERE NOT EXISTS (
SELECT 1 FROM user_attribute_definitions WHERE key = 'wechat' AND deleted_at IS NULL
);
-- Step 2: Migrate existing wechat values to user_attribute_values
-- Only migrate non-empty values
INSERT INTO user_attribute_values (user_id, attribute_id, value, created_at, updated_at)
SELECT
u.id,
(SELECT id FROM user_attribute_definitions WHERE key = 'wechat' AND deleted_at IS NULL LIMIT 1),
u.wechat,
NOW(),
NOW()
FROM users u
WHERE u.wechat IS NOT NULL
AND u.wechat != ''
AND u.deleted_at IS NULL
AND NOT EXISTS (
SELECT 1 FROM user_attribute_values uav
WHERE uav.user_id = u.id
AND uav.attribute_id = (SELECT id FROM user_attribute_definitions WHERE key = 'wechat' AND deleted_at IS NULL LIMIT 1)
);
-- Step 3: Update display_order to ensure wechat appears first
UPDATE user_attribute_definitions
SET display_order = -1
WHERE key = 'wechat' AND deleted_at IS NULL;
-- Reorder all attributes starting from 0
WITH ordered AS (
SELECT id, ROW_NUMBER() OVER (ORDER BY display_order, id) - 1 as new_order
FROM user_attribute_definitions
WHERE deleted_at IS NULL
)
UPDATE user_attribute_definitions
SET display_order = ordered.new_order
FROM ordered
WHERE user_attribute_definitions.id = ordered.id;
-- Step 4: Drop the redundant wechat column from users table
ALTER TABLE users DROP COLUMN IF EXISTS wechat;
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
-- Restore wechat column
ALTER TABLE users ADD COLUMN IF NOT EXISTS wechat VARCHAR(100) DEFAULT '';
-- Copy attribute values back to users.wechat column
UPDATE users u
SET wechat = uav.value
FROM user_attribute_values uav
JOIN user_attribute_definitions uad ON uav.attribute_id = uad.id
WHERE uav.user_id = u.id
AND uad.key = 'wechat'
AND uad.deleted_at IS NULL;
-- Delete migrated attribute values
DELETE FROM user_attribute_values
WHERE attribute_id IN (
SELECT id FROM user_attribute_definitions WHERE key = 'wechat' AND deleted_at IS NULL
);
-- Soft-delete the wechat attribute definition
UPDATE user_attribute_definitions
SET deleted_at = NOW()
WHERE key = 'wechat' AND deleted_at IS NULL;
-- +goose StatementEnd