497 lines
22 KiB
SQL
497 lines
22 KiB
SQL
-- ============================================
|
||
-- Migration: contribution-service 初始化
|
||
--
|
||
-- 包含所有表的创建:
|
||
-- 1. CDC 同步表 (synced_users, synced_adoptions, synced_referrals)
|
||
-- 2. 算力账户表 (contribution_accounts)
|
||
-- 3. 算力明细表 (contribution_records)
|
||
-- 4. 解锁事件表 (unlock_events)
|
||
-- 5. 未分配算力表 (unallocated_contributions)
|
||
-- 6. 系统账户表 (system_accounts, system_contribution_records)
|
||
-- 7. 快照与统计表 (daily_contribution_snapshots, user_team_stats)
|
||
-- 8. CDC 同步状态表 (cdc_sync_progress, processed_events)
|
||
-- 9. 配置表 (contribution_configs, distribution_rate_configs)
|
||
-- 10. Outbox 事件表 (outbox_events)
|
||
-- ============================================
|
||
|
||
-- ============================================
|
||
-- 1. CDC 同步数据表
|
||
-- ============================================
|
||
|
||
-- 同步的用户数据
|
||
CREATE TABLE "synced_users" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
"original_user_id" BIGINT NOT NULL,
|
||
"phone" VARCHAR(20),
|
||
"status" VARCHAR(20),
|
||
"source_sequence_num" BIGINT NOT NULL,
|
||
"synced_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"contribution_calculated" BOOLEAN NOT NULL DEFAULT false,
|
||
"contribution_calculated_at" TIMESTAMP(3),
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "synced_users_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "synced_users_account_sequence_key" ON "synced_users"("account_sequence");
|
||
CREATE INDEX "synced_users_original_user_id_idx" ON "synced_users"("original_user_id");
|
||
CREATE INDEX "synced_users_contribution_calculated_idx" ON "synced_users"("contribution_calculated");
|
||
|
||
-- 同步的认种数据
|
||
CREATE TABLE "synced_adoptions" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"original_adoption_id" BIGINT NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
"tree_count" INTEGER NOT NULL,
|
||
"adoption_date" DATE NOT NULL,
|
||
"status" VARCHAR(20),
|
||
"contribution_per_tree" DECIMAL(20,10) NOT NULL,
|
||
"source_sequence_num" BIGINT NOT NULL,
|
||
"synced_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"contribution_distributed" BOOLEAN NOT NULL DEFAULT false,
|
||
"contribution_distributed_at" TIMESTAMP(3),
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "synced_adoptions_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "synced_adoptions_original_adoption_id_key" ON "synced_adoptions"("original_adoption_id");
|
||
CREATE INDEX "synced_adoptions_account_sequence_idx" ON "synced_adoptions"("account_sequence");
|
||
CREATE INDEX "synced_adoptions_adoption_date_idx" ON "synced_adoptions"("adoption_date");
|
||
CREATE INDEX "synced_adoptions_contribution_distributed_idx" ON "synced_adoptions"("contribution_distributed");
|
||
|
||
-- 同步的推荐关系数据
|
||
CREATE TABLE "synced_referrals" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
"referrer_account_sequence" VARCHAR(20),
|
||
"ancestor_path" TEXT,
|
||
"depth" INTEGER NOT NULL DEFAULT 0,
|
||
"source_sequence_num" BIGINT NOT NULL,
|
||
"synced_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "synced_referrals_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "synced_referrals_account_sequence_key" ON "synced_referrals"("account_sequence");
|
||
CREATE INDEX "synced_referrals_referrer_account_sequence_idx" ON "synced_referrals"("referrer_account_sequence");
|
||
|
||
-- ============================================
|
||
-- 2. 算力账户表
|
||
-- ============================================
|
||
|
||
-- 算力账户表(汇总)
|
||
-- 设计说明:
|
||
-- - 个人算力:自己认种,立即生效
|
||
-- - 层级算力:下级1-15层认种的分成,每层0.5%,共7.5%
|
||
-- - 加成算力:团队加成,3档各2.5%,共7.5%
|
||
-- 解锁规则:
|
||
-- - 自己认种:解锁层级1-5 + 加成第1档
|
||
-- - 直推≥2人认种:解锁加成第2档
|
||
-- - 直推≥3人认种:解锁层级6-10
|
||
-- - 直推≥4人认种:解锁加成第3档
|
||
-- - 直推≥5人认种:解锁层级11-15
|
||
CREATE TABLE "contribution_accounts" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 个人算力(立即生效)
|
||
"personal_contribution" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
|
||
-- 15级层级算力(待解锁)
|
||
-- 第1档(1-5级):自己认种解锁
|
||
"level_1_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_2_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_3_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_4_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_5_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
-- 第2档(6-10级):直推≥3人认种解锁
|
||
"level_6_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_7_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_8_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_9_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_10_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
-- 第3档(11-15级):直推≥5人认种解锁
|
||
"level_11_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_12_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_13_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_14_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"level_15_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
|
||
-- 3档加成算力(待解锁)
|
||
"bonus_tier_1_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"bonus_tier_2_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"bonus_tier_3_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
|
||
-- 汇总字段
|
||
"total_level_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"total_bonus_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"total_pending" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"total_unlocked" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"effective_contribution" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
|
||
-- 解锁条件状态
|
||
"has_adopted" BOOLEAN NOT NULL DEFAULT false,
|
||
"direct_referral_adopted_count" INTEGER NOT NULL DEFAULT 0,
|
||
"unlocked_level_depth" INTEGER NOT NULL DEFAULT 0,
|
||
"unlocked_bonus_tiers" INTEGER NOT NULL DEFAULT 0,
|
||
|
||
-- 乐观锁
|
||
"version" INTEGER NOT NULL DEFAULT 1,
|
||
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"updated_at" TIMESTAMP(3) NOT NULL,
|
||
|
||
CONSTRAINT "contribution_accounts_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "contribution_accounts_account_sequence_key" ON "contribution_accounts"("account_sequence");
|
||
CREATE INDEX "contribution_accounts_effective_contribution_idx" ON "contribution_accounts"("effective_contribution" DESC);
|
||
CREATE INDEX "contribution_accounts_has_adopted_idx" ON "contribution_accounts"("has_adopted");
|
||
CREATE INDEX "contribution_accounts_direct_referral_adopted_count_idx" ON "contribution_accounts"("direct_referral_adopted_count");
|
||
|
||
-- 添加字段注释
|
||
COMMENT ON COLUMN "contribution_accounts"."level_1_pending" IS '第1级待解锁算力 (0.5%)';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_2_pending" IS '第2级待解锁算力 (0.5%)';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_3_pending" IS '第3级待解锁算力 (0.5%)';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_4_pending" IS '第4级待解锁算力 (0.5%)';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_5_pending" IS '第5级待解锁算力 (0.5%)';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_6_pending" IS '第6级待解锁算力 (0.5%) - 直推≥3人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_7_pending" IS '第7级待解锁算力 (0.5%) - 直推≥3人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_8_pending" IS '第8级待解锁算力 (0.5%) - 直推≥3人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_9_pending" IS '第9级待解锁算力 (0.5%) - 直推≥3人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_10_pending" IS '第10级待解锁算力 (0.5%) - 直推≥3人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_11_pending" IS '第11级待解锁算力 (0.5%) - 直推≥5人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_12_pending" IS '第12级待解锁算力 (0.5%) - 直推≥5人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_13_pending" IS '第13级待解锁算力 (0.5%) - 直推≥5人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_14_pending" IS '第14级待解锁算力 (0.5%) - 直推≥5人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."level_15_pending" IS '第15级待解锁算力 (0.5%) - 直推≥5人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."bonus_tier_1_pending" IS '第1档加成待解锁算力 (2.5%) - 自己认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."bonus_tier_2_pending" IS '第2档加成待解锁算力 (2.5%) - 直推≥2人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."bonus_tier_3_pending" IS '第3档加成待解锁算力 (2.5%) - 直推≥4人认种解锁';
|
||
COMMENT ON COLUMN "contribution_accounts"."unlocked_level_depth" IS '已解锁层级深度: 0=未解锁, 5=1-5级, 10=1-10级, 15=全部';
|
||
COMMENT ON COLUMN "contribution_accounts"."unlocked_bonus_tiers" IS '已解锁加成档位数: 0/1/2/3';
|
||
COMMENT ON COLUMN "contribution_accounts"."effective_contribution" IS '有效算力 = 个人算力 + 已解锁算力';
|
||
|
||
-- ============================================
|
||
-- 3. 算力明细表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "contribution_records" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 来源信息(可追溯)
|
||
"source_type" VARCHAR(30) NOT NULL,
|
||
"source_adoption_id" BIGINT NOT NULL,
|
||
"source_account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 计算参数(审计用)
|
||
"tree_count" INTEGER NOT NULL,
|
||
"base_contribution" DECIMAL(20,10) NOT NULL,
|
||
"distribution_rate" DECIMAL(10,6) NOT NULL,
|
||
"level_depth" INTEGER,
|
||
"bonus_tier" INTEGER,
|
||
|
||
-- 金额
|
||
"amount" DECIMAL(30,10) NOT NULL,
|
||
|
||
-- 解锁状态
|
||
"status" VARCHAR(20) NOT NULL DEFAULT 'PENDING',
|
||
"unlocked_at" TIMESTAMP(3),
|
||
"unlock_reason" VARCHAR(200),
|
||
|
||
-- 有效期
|
||
"effective_date" DATE NOT NULL,
|
||
"expire_date" DATE NOT NULL,
|
||
"is_expired" BOOLEAN NOT NULL DEFAULT false,
|
||
"expired_at" TIMESTAMP(3),
|
||
|
||
-- 备注
|
||
"remark" VARCHAR(500),
|
||
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "contribution_records_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE INDEX "contribution_records_account_sequence_status_idx" ON "contribution_records"("account_sequence", "status");
|
||
CREATE INDEX "contribution_records_account_sequence_created_at_idx" ON "contribution_records"("account_sequence", "created_at" DESC);
|
||
CREATE INDEX "contribution_records_source_adoption_id_idx" ON "contribution_records"("source_adoption_id");
|
||
CREATE INDEX "contribution_records_source_account_sequence_idx" ON "contribution_records"("source_account_sequence");
|
||
CREATE INDEX "contribution_records_source_type_idx" ON "contribution_records"("source_type");
|
||
CREATE INDEX "contribution_records_status_idx" ON "contribution_records"("status");
|
||
CREATE INDEX "contribution_records_expire_date_idx" ON "contribution_records"("expire_date");
|
||
CREATE INDEX "contribution_records_is_expired_idx" ON "contribution_records"("is_expired");
|
||
|
||
COMMENT ON COLUMN "contribution_records"."status" IS '状态: PENDING(待解锁)/UNLOCKED(已解锁)/EFFECTIVE(已生效)';
|
||
COMMENT ON COLUMN "contribution_records"."source_type" IS '来源类型: PERSONAL/LEVEL_1~15/BONUS_TIER_1~3';
|
||
|
||
-- ============================================
|
||
-- 4. 解锁事件表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "unlock_events" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 触发信息
|
||
"trigger_type" VARCHAR(30) NOT NULL,
|
||
"trigger_adoption_id" BIGINT NOT NULL,
|
||
"trigger_account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 解锁内容
|
||
"unlock_type" VARCHAR(30) NOT NULL,
|
||
"unlock_condition" VARCHAR(100) NOT NULL,
|
||
|
||
-- 解锁前后状态
|
||
"before_direct_referral_count" INTEGER NOT NULL,
|
||
"after_direct_referral_count" INTEGER NOT NULL,
|
||
"before_unlocked_level_depth" INTEGER NOT NULL,
|
||
"after_unlocked_level_depth" INTEGER NOT NULL,
|
||
"before_unlocked_bonus_tiers" INTEGER NOT NULL,
|
||
"after_unlocked_bonus_tiers" INTEGER NOT NULL,
|
||
|
||
-- 解锁金额
|
||
"unlocked_amount" DECIMAL(30,10) NOT NULL,
|
||
"unlocked_record_count" INTEGER NOT NULL,
|
||
|
||
-- 备注
|
||
"remark" VARCHAR(500),
|
||
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "unlock_events_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE INDEX "unlock_events_account_sequence_idx" ON "unlock_events"("account_sequence");
|
||
CREATE INDEX "unlock_events_trigger_account_sequence_idx" ON "unlock_events"("trigger_account_sequence");
|
||
CREATE INDEX "unlock_events_trigger_adoption_id_idx" ON "unlock_events"("trigger_adoption_id");
|
||
CREATE INDEX "unlock_events_unlock_type_idx" ON "unlock_events"("unlock_type");
|
||
CREATE INDEX "unlock_events_created_at_idx" ON "unlock_events"("created_at" DESC);
|
||
|
||
COMMENT ON TABLE "unlock_events" IS '解锁事件记录表 - 记录每次算力解锁的触发原因和结果';
|
||
COMMENT ON COLUMN "unlock_events"."trigger_type" IS '触发类型: SELF_ADOPT(自己认种) / REFERRAL_ADOPT(直推认种)';
|
||
COMMENT ON COLUMN "unlock_events"."unlock_type" IS '解锁类型: LEVEL_1_5/LEVEL_6_10/LEVEL_11_15/BONUS_TIER_1/BONUS_TIER_2/BONUS_TIER_3';
|
||
COMMENT ON COLUMN "unlock_events"."unlock_condition" IS '解锁条件描述,如"自己认种"、"直推认种人数达到3人"';
|
||
|
||
-- ============================================
|
||
-- 5. 未分配算力表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "unallocated_contributions" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"source_adoption_id" BIGINT NOT NULL,
|
||
"source_account_sequence" VARCHAR(20) NOT NULL,
|
||
|
||
-- 未分配类型
|
||
"unalloc_type" VARCHAR(30) NOT NULL,
|
||
"would_be_account_sequence" VARCHAR(20),
|
||
"level_depth" INTEGER,
|
||
"bonus_tier" INTEGER,
|
||
|
||
"amount" DECIMAL(30,10) NOT NULL,
|
||
"reason" VARCHAR(200),
|
||
|
||
-- 分配状态
|
||
"status" VARCHAR(20) NOT NULL DEFAULT 'PENDING',
|
||
"allocated_at" TIMESTAMP(3),
|
||
"allocated_to_account_sequence" VARCHAR(20),
|
||
|
||
-- 有效期
|
||
"effective_date" DATE NOT NULL,
|
||
"expire_date" DATE NOT NULL,
|
||
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "unallocated_contributions_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE INDEX "unallocated_contributions_source_adoption_id_idx" ON "unallocated_contributions"("source_adoption_id");
|
||
CREATE INDEX "unallocated_contributions_would_be_account_sequence_idx" ON "unallocated_contributions"("would_be_account_sequence");
|
||
CREATE INDEX "unallocated_contributions_unalloc_type_idx" ON "unallocated_contributions"("unalloc_type");
|
||
CREATE INDEX "unallocated_contributions_status_idx" ON "unallocated_contributions"("status");
|
||
|
||
-- ============================================
|
||
-- 6. 系统账户表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "system_accounts" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_type" VARCHAR(20) NOT NULL,
|
||
"name" VARCHAR(100) NOT NULL,
|
||
"contribution_balance" DECIMAL(30,10) NOT NULL DEFAULT 0,
|
||
"contribution_never_expires" BOOLEAN NOT NULL DEFAULT false,
|
||
"version" INTEGER NOT NULL DEFAULT 1,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"updated_at" TIMESTAMP(3) NOT NULL,
|
||
|
||
CONSTRAINT "system_accounts_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "system_accounts_account_type_key" ON "system_accounts"("account_type");
|
||
|
||
CREATE TABLE "system_contribution_records" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"system_account_id" BIGINT NOT NULL,
|
||
"source_adoption_id" BIGINT NOT NULL,
|
||
"source_account_sequence" VARCHAR(20) NOT NULL,
|
||
"distribution_rate" DECIMAL(10,6) NOT NULL,
|
||
"amount" DECIMAL(30,10) NOT NULL,
|
||
"effective_date" DATE NOT NULL,
|
||
"expire_date" DATE,
|
||
"is_expired" BOOLEAN NOT NULL DEFAULT false,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "system_contribution_records_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE INDEX "system_contribution_records_system_account_id_idx" ON "system_contribution_records"("system_account_id");
|
||
CREATE INDEX "system_contribution_records_source_adoption_id_idx" ON "system_contribution_records"("source_adoption_id");
|
||
|
||
ALTER TABLE "system_contribution_records" ADD CONSTRAINT "system_contribution_records_system_account_id_fkey" FOREIGN KEY ("system_account_id") REFERENCES "system_accounts"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
||
|
||
-- ============================================
|
||
-- 7. 快照与统计表
|
||
-- ============================================
|
||
|
||
-- 每日算力快照
|
||
CREATE TABLE "daily_contribution_snapshots" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"snapshot_date" DATE NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
"effective_contribution" DECIMAL(30,10) NOT NULL,
|
||
"network_total_contribution" DECIMAL(30,10) NOT NULL,
|
||
"contribution_ratio" DECIMAL(30,18) NOT NULL,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "daily_contribution_snapshots_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "daily_contribution_snapshots_snapshot_date_account_sequence_key" ON "daily_contribution_snapshots"("snapshot_date", "account_sequence");
|
||
CREATE INDEX "daily_contribution_snapshots_snapshot_date_idx" ON "daily_contribution_snapshots"("snapshot_date");
|
||
CREATE INDEX "daily_contribution_snapshots_account_sequence_idx" ON "daily_contribution_snapshots"("account_sequence");
|
||
|
||
-- 用户团队统计
|
||
CREATE TABLE "user_team_stats" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"account_sequence" VARCHAR(20) NOT NULL,
|
||
"stats_date" DATE NOT NULL,
|
||
"level_1_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_2_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_3_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_4_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_5_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_6_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_7_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_8_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_9_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_10_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_11_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_12_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_13_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_14_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"level_15_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"total_team_trees" INTEGER NOT NULL DEFAULT 0,
|
||
"direct_adopted_referrals" INTEGER NOT NULL DEFAULT 0,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "user_team_stats_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "user_team_stats_account_sequence_stats_date_key" ON "user_team_stats"("account_sequence", "stats_date");
|
||
CREATE INDEX "user_team_stats_account_sequence_idx" ON "user_team_stats"("account_sequence");
|
||
CREATE INDEX "user_team_stats_stats_date_idx" ON "user_team_stats"("stats_date");
|
||
|
||
-- ============================================
|
||
-- 8. CDC 同步状态表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "cdc_sync_progress" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"source_topic" VARCHAR(100) NOT NULL,
|
||
"last_sequence_num" BIGINT NOT NULL DEFAULT 0,
|
||
"last_synced_at" TIMESTAMP(3),
|
||
"updated_at" TIMESTAMP(3) NOT NULL,
|
||
|
||
CONSTRAINT "cdc_sync_progress_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "cdc_sync_progress_source_topic_key" ON "cdc_sync_progress"("source_topic");
|
||
|
||
CREATE TABLE "processed_events" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"event_id" VARCHAR(100) NOT NULL,
|
||
"event_type" VARCHAR(50) NOT NULL,
|
||
"source_service" VARCHAR(50),
|
||
"processed_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "processed_events_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "processed_events_event_id_key" ON "processed_events"("event_id");
|
||
CREATE INDEX "processed_events_event_type_idx" ON "processed_events"("event_type");
|
||
CREATE INDEX "processed_events_processed_at_idx" ON "processed_events"("processed_at");
|
||
|
||
-- ============================================
|
||
-- 9. 配置表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "contribution_configs" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"base_contribution" DECIMAL(20,10) NOT NULL DEFAULT 22617,
|
||
"increment_percentage" DECIMAL(10,6) NOT NULL DEFAULT 0.003,
|
||
"unit_size" INTEGER NOT NULL DEFAULT 100,
|
||
"start_tree_number" INTEGER NOT NULL DEFAULT 1000,
|
||
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "contribution_configs_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE INDEX "contribution_configs_is_active_idx" ON "contribution_configs"("is_active");
|
||
|
||
CREATE TABLE "distribution_rate_configs" (
|
||
"id" BIGSERIAL NOT NULL,
|
||
"rate_type" VARCHAR(30) NOT NULL,
|
||
"rate_value" DECIMAL(10,6) NOT NULL,
|
||
"description" VARCHAR(100),
|
||
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
|
||
CONSTRAINT "distribution_rate_configs_pkey" PRIMARY KEY ("id")
|
||
);
|
||
|
||
CREATE UNIQUE INDEX "distribution_rate_configs_rate_type_key" ON "distribution_rate_configs"("rate_type");
|
||
CREATE INDEX "distribution_rate_configs_is_active_idx" ON "distribution_rate_configs"("is_active");
|
||
|
||
-- ============================================
|
||
-- 10. Outbox 事件表
|
||
-- ============================================
|
||
|
||
CREATE TABLE "outbox_events" (
|
||
"outbox_id" BIGSERIAL NOT NULL,
|
||
"event_type" VARCHAR(100) NOT NULL,
|
||
"topic" VARCHAR(100) NOT NULL,
|
||
"key" VARCHAR(200) NOT NULL,
|
||
"payload" JSONB NOT NULL,
|
||
"aggregate_id" VARCHAR(100) NOT NULL,
|
||
"aggregate_type" VARCHAR(50) NOT NULL,
|
||
"status" VARCHAR(20) NOT NULL DEFAULT 'PENDING',
|
||
"retry_count" INTEGER NOT NULL DEFAULT 0,
|
||
"max_retries" INTEGER NOT NULL DEFAULT 5,
|
||
"last_error" TEXT,
|
||
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
"published_at" TIMESTAMP(3),
|
||
"next_retry_at" TIMESTAMP(3),
|
||
|
||
CONSTRAINT "outbox_events_pkey" PRIMARY KEY ("outbox_id")
|
||
);
|
||
|
||
CREATE INDEX "outbox_events_status_created_at_idx" ON "outbox_events"("status", "created_at");
|
||
CREATE INDEX "outbox_events_status_next_retry_at_idx" ON "outbox_events"("status", "next_retry_at");
|
||
CREATE INDEX "outbox_events_aggregate_type_aggregate_id_idx" ON "outbox_events"("aggregate_type", "aggregate_id");
|
||
CREATE INDEX "outbox_events_topic_idx" ON "outbox_events"("topic");
|