chore(db): 添加用户画像系统数据库迁移

新增表:
- tag_categories: 标签分类
- user_tags: 用户标签定义
- user_tag_assignments: 用户-标签关联
- user_classification_rules: 分类规则
- user_features: 用户特征 (RFM等)
- audience_segments: 人群包
- user_tag_logs: 标签变更日志
- notification_tag_targets: 通知-标签关联
- notification_user_targets: 通知-用户关联

新增枚举:
- TagType, TagValueType, TagAction, SegmentUsageType, TargetLogic

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

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
hailin 2025-12-24 16:43:19 -08:00
parent b5e45c4532
commit fff88d0323
1 changed files with 255 additions and 0 deletions

View File

@ -0,0 +1,255 @@
-- =============================================================================
-- User Profile System Migration
-- 用户画像系统:标签管理、分类规则、人群包
-- =============================================================================
-- -----------------------------------------------------------------------------
-- 1. 枚举类型
-- -----------------------------------------------------------------------------
-- 标签类型
CREATE TYPE "TagType" AS ENUM ('MANUAL', 'AUTO', 'COMPUTED', 'SYSTEM');
-- 标签值类型
CREATE TYPE "TagValueType" AS ENUM ('BOOLEAN', 'ENUM', 'NUMBER', 'STRING');
-- 标签变更操作
CREATE TYPE "TagAction" AS ENUM ('ASSIGN', 'UPDATE', 'REMOVE', 'EXPIRE');
-- 人群包用途
CREATE TYPE "SegmentUsageType" AS ENUM ('GENERAL', 'NOTIFICATION', 'ADVERTISING', 'ANALYTICS');
-- -----------------------------------------------------------------------------
-- 2. 标签分类表
-- -----------------------------------------------------------------------------
CREATE TABLE "tag_categories" (
"id" TEXT NOT NULL,
"code" VARCHAR(50) NOT NULL,
"name" VARCHAR(100) NOT NULL,
"description" TEXT,
"sort_order" INTEGER NOT NULL DEFAULT 0,
"is_enabled" BOOLEAN NOT NULL DEFAULT true,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
CONSTRAINT "tag_categories_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "tag_categories_code_key" ON "tag_categories"("code");
CREATE INDEX "tag_categories_code_idx" ON "tag_categories"("code");
CREATE INDEX "tag_categories_is_enabled_idx" ON "tag_categories"("is_enabled");
-- -----------------------------------------------------------------------------
-- 3. 用户分类规则表 (必须在 user_tags 之前创建,因为有外键引用)
-- -----------------------------------------------------------------------------
CREATE TABLE "user_classification_rules" (
"id" TEXT NOT NULL,
"name" VARCHAR(100) NOT NULL,
"description" TEXT,
"conditions" JSONB NOT NULL,
"is_enabled" BOOLEAN NOT NULL DEFAULT true,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
CONSTRAINT "user_classification_rules_pkey" PRIMARY KEY ("id")
);
-- -----------------------------------------------------------------------------
-- 4. 用户标签定义表
-- -----------------------------------------------------------------------------
CREATE TABLE "user_tags" (
"id" TEXT NOT NULL,
"category_id" TEXT,
"code" VARCHAR(50) NOT NULL,
"name" VARCHAR(100) NOT NULL,
"description" TEXT,
"color" VARCHAR(20),
"type" "TagType" NOT NULL DEFAULT 'MANUAL',
"value_type" "TagValueType" NOT NULL DEFAULT 'BOOLEAN',
"enum_values" JSONB,
"rule_id" TEXT,
"is_advertisable" BOOLEAN NOT NULL DEFAULT true,
"estimated_users" INTEGER,
"is_enabled" BOOLEAN NOT NULL DEFAULT true,
"sort_order" INTEGER NOT NULL DEFAULT 0,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
CONSTRAINT "user_tags_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "user_tags_code_key" ON "user_tags"("code");
CREATE UNIQUE INDEX "user_tags_rule_id_key" ON "user_tags"("rule_id");
CREATE INDEX "user_tags_category_id_idx" ON "user_tags"("category_id");
CREATE INDEX "user_tags_code_idx" ON "user_tags"("code");
CREATE INDEX "user_tags_type_idx" ON "user_tags"("type");
CREATE INDEX "user_tags_is_enabled_idx" ON "user_tags"("is_enabled");
CREATE INDEX "user_tags_is_advertisable_idx" ON "user_tags"("is_advertisable");
-- 外键约束
ALTER TABLE "user_tags" ADD CONSTRAINT "user_tags_category_id_fkey"
FOREIGN KEY ("category_id") REFERENCES "tag_categories"("id") ON DELETE SET NULL ON UPDATE CASCADE;
ALTER TABLE "user_tags" ADD CONSTRAINT "user_tags_rule_id_fkey"
FOREIGN KEY ("rule_id") REFERENCES "user_classification_rules"("id") ON DELETE SET NULL ON UPDATE CASCADE;
-- -----------------------------------------------------------------------------
-- 5. 用户-标签关联表
-- -----------------------------------------------------------------------------
CREATE TABLE "user_tag_assignments" (
"id" TEXT NOT NULL,
"account_sequence" VARCHAR(12) NOT NULL,
"tag_id" TEXT NOT NULL,
"value" VARCHAR(100),
"assigned_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"assigned_by" TEXT,
"expires_at" TIMESTAMP(3),
"source" VARCHAR(50),
CONSTRAINT "user_tag_assignments_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "user_tag_assignments_account_sequence_tag_id_key" ON "user_tag_assignments"("account_sequence", "tag_id");
CREATE INDEX "user_tag_assignments_account_sequence_idx" ON "user_tag_assignments"("account_sequence");
CREATE INDEX "user_tag_assignments_tag_id_idx" ON "user_tag_assignments"("tag_id");
CREATE INDEX "user_tag_assignments_value_idx" ON "user_tag_assignments"("value");
CREATE INDEX "user_tag_assignments_expires_at_idx" ON "user_tag_assignments"("expires_at");
ALTER TABLE "user_tag_assignments" ADD CONSTRAINT "user_tag_assignments_tag_id_fkey"
FOREIGN KEY ("tag_id") REFERENCES "user_tags"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- -----------------------------------------------------------------------------
-- 6. 用户特征表
-- -----------------------------------------------------------------------------
CREATE TABLE "user_features" (
"id" TEXT NOT NULL,
"account_sequence" VARCHAR(12) NOT NULL,
"rfm_recency" INTEGER,
"rfm_frequency" INTEGER,
"rfm_monetary" DECIMAL(18,2),
"rfm_score" INTEGER,
"active_level" VARCHAR(20),
"last_active_at" TIMESTAMP(3),
"value_level" VARCHAR(20),
"lifetime_value" DECIMAL(18,2),
"lifecycle_stage" VARCHAR(20),
"custom_features" JSONB,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
CONSTRAINT "user_features_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "user_features_account_sequence_key" ON "user_features"("account_sequence");
CREATE INDEX "user_features_rfm_score_idx" ON "user_features"("rfm_score");
CREATE INDEX "user_features_active_level_idx" ON "user_features"("active_level");
CREATE INDEX "user_features_value_level_idx" ON "user_features"("value_level");
CREATE INDEX "user_features_lifecycle_stage_idx" ON "user_features"("lifecycle_stage");
-- -----------------------------------------------------------------------------
-- 7. 人群包表
-- -----------------------------------------------------------------------------
CREATE TABLE "audience_segments" (
"id" TEXT NOT NULL,
"name" VARCHAR(100) NOT NULL,
"description" TEXT,
"conditions" JSONB NOT NULL,
"estimated_users" INTEGER,
"last_calculated" TIMESTAMP(3),
"usage_type" "SegmentUsageType" NOT NULL DEFAULT 'GENERAL',
"is_enabled" BOOLEAN NOT NULL DEFAULT true,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
"updated_at" TIMESTAMP(3) NOT NULL,
"created_by" TEXT NOT NULL,
CONSTRAINT "audience_segments_pkey" PRIMARY KEY ("id")
);
CREATE INDEX "audience_segments_usage_type_idx" ON "audience_segments"("usage_type");
CREATE INDEX "audience_segments_is_enabled_idx" ON "audience_segments"("is_enabled");
-- -----------------------------------------------------------------------------
-- 8. 标签变更日志表
-- -----------------------------------------------------------------------------
CREATE TABLE "user_tag_logs" (
"id" TEXT NOT NULL,
"account_sequence" VARCHAR(12) NOT NULL,
"tag_code" VARCHAR(50) NOT NULL,
"action" "TagAction" NOT NULL,
"old_value" VARCHAR(100),
"new_value" VARCHAR(100),
"reason" VARCHAR(200),
"operator_id" TEXT,
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT "user_tag_logs_pkey" PRIMARY KEY ("id")
);
CREATE INDEX "user_tag_logs_account_sequence_created_at_idx" ON "user_tag_logs"("account_sequence", "created_at");
CREATE INDEX "user_tag_logs_tag_code_idx" ON "user_tag_logs"("tag_code");
CREATE INDEX "user_tag_logs_action_idx" ON "user_tag_logs"("action");
CREATE INDEX "user_tag_logs_created_at_idx" ON "user_tag_logs"("created_at");
-- -----------------------------------------------------------------------------
-- 9. 通知-标签关联表 (用于 BY_TAG 定向)
-- -----------------------------------------------------------------------------
CREATE TABLE "notification_tag_targets" (
"id" TEXT NOT NULL,
"notification_id" TEXT NOT NULL,
"tag_id" TEXT NOT NULL,
CONSTRAINT "notification_tag_targets_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "notification_tag_targets_notification_id_tag_id_key" ON "notification_tag_targets"("notification_id", "tag_id");
CREATE INDEX "notification_tag_targets_tag_id_idx" ON "notification_tag_targets"("tag_id");
ALTER TABLE "notification_tag_targets" ADD CONSTRAINT "notification_tag_targets_notification_id_fkey"
FOREIGN KEY ("notification_id") REFERENCES "notifications"("id") ON DELETE CASCADE ON UPDATE CASCADE;
ALTER TABLE "notification_tag_targets" ADD CONSTRAINT "notification_tag_targets_tag_id_fkey"
FOREIGN KEY ("tag_id") REFERENCES "user_tags"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- -----------------------------------------------------------------------------
-- 10. 通知-用户关联表 (用于 SPECIFIC 定向)
-- -----------------------------------------------------------------------------
CREATE TABLE "notification_user_targets" (
"id" TEXT NOT NULL,
"notification_id" TEXT NOT NULL,
"account_sequence" VARCHAR(12) NOT NULL,
CONSTRAINT "notification_user_targets_pkey" PRIMARY KEY ("id")
);
CREATE UNIQUE INDEX "notification_user_targets_notification_id_account_sequence_key" ON "notification_user_targets"("notification_id", "account_sequence");
CREATE INDEX "notification_user_targets_account_sequence_idx" ON "notification_user_targets"("account_sequence");
ALTER TABLE "notification_user_targets" ADD CONSTRAINT "notification_user_targets_notification_id_fkey"
FOREIGN KEY ("notification_id") REFERENCES "notifications"("id") ON DELETE CASCADE ON UPDATE CASCADE;
-- -----------------------------------------------------------------------------
-- 11. 修改通知表:添加 target_logic 字段,修改 targetType 枚举
-- -----------------------------------------------------------------------------
-- 先更新 TargetType 枚举添加新值
ALTER TYPE "TargetType" ADD VALUE IF NOT EXISTS 'BY_TAG';
ALTER TYPE "TargetType" ADD VALUE IF NOT EXISTS 'SPECIFIC';
-- 创建 TargetLogic 枚举
DO $$ BEGIN
CREATE TYPE "TargetLogic" AS ENUM ('ANY', 'ALL');
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- 添加 target_logic 列
ALTER TABLE "notifications" ADD COLUMN IF NOT EXISTS "target_logic" "TargetLogic" NOT NULL DEFAULT 'ANY';