431 lines
16 KiB
SQL
431 lines
16 KiB
SQL
-- ============================================================================
|
|
-- mining-wallet-service 初始化 migration
|
|
-- 合并自: 20260111000000_init, 20260112180000_add_contribution_balance,
|
|
-- 20260112220000_remove_blockchain_tables
|
|
-- 注意: 区块链相关表已移除
|
|
-- ============================================================================
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "SystemAccountType" AS ENUM ('HEADQUARTERS', 'OPERATION', 'PROVINCE', 'CITY', 'FEE', 'HOT_WALLET', 'COLD_WALLET');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "PoolAccountType" AS ENUM ('SHARE_POOL', 'BLACK_HOLE_POOL', 'CIRCULATION_POOL');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "UserWalletType" AS ENUM ('CONTRIBUTION', 'TOKEN_STORAGE', 'GREEN_POINTS');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "AssetType" AS ENUM ('SHARE', 'USDT', 'GREEN_POINT', 'CONTRIBUTION');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "TransactionType" AS ENUM ('MINING_REWARD', 'MINING_DISTRIBUTE', 'TRANSFER_IN', 'TRANSFER_OUT', 'INTERNAL_TRANSFER', 'TRADE_BUY', 'TRADE_SELL', 'WITHDRAW', 'DEPOSIT', 'BURN', 'FREEZE', 'UNFREEZE', 'FEE_COLLECT', 'FEE_DISTRIBUTE', 'POOL_INJECT', 'POOL_EXTRACT', 'ADJUSTMENT', 'INITIAL_INJECT');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "CounterpartyType" AS ENUM ('USER', 'SYSTEM_ACCOUNT', 'POOL', 'BLOCKCHAIN', 'EXTERNAL');
|
|
|
|
-- CreateEnum
|
|
CREATE TYPE "OutboxStatus" AS ENUM ('PENDING', 'PUBLISHED', 'FAILED');
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "provinces" (
|
|
"id" TEXT NOT NULL,
|
|
"code" TEXT NOT NULL,
|
|
"name" TEXT NOT NULL,
|
|
"status" TEXT NOT NULL DEFAULT 'ACTIVE',
|
|
"createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updatedAt" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "provinces_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "cities" (
|
|
"id" TEXT NOT NULL,
|
|
"province_id" TEXT NOT NULL,
|
|
"code" TEXT NOT NULL,
|
|
"name" TEXT NOT NULL,
|
|
"status" TEXT NOT NULL DEFAULT 'ACTIVE',
|
|
"createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updatedAt" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "cities_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "user_region_mappings" (
|
|
"id" TEXT NOT NULL,
|
|
"account_sequence" TEXT NOT NULL,
|
|
"city_id" TEXT NOT NULL,
|
|
"assigned_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"assigned_by" TEXT,
|
|
"createdAt" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updatedAt" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "user_region_mappings_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "system_accounts" (
|
|
"id" TEXT NOT NULL,
|
|
"account_type" "SystemAccountType" NOT NULL,
|
|
"name" TEXT NOT NULL,
|
|
"code" TEXT NOT NULL,
|
|
"province_id" TEXT,
|
|
"city_id" TEXT,
|
|
"share_balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"usdt_balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"green_point_balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"contribution_balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"frozen_share" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"frozen_usdt" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_inflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_outflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"blockchain_address" TEXT,
|
|
"description" TEXT,
|
|
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updated_at" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "system_accounts_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "system_account_transactions" (
|
|
"id" TEXT NOT NULL,
|
|
"system_account_id" TEXT NOT NULL,
|
|
"transaction_type" "TransactionType" NOT NULL,
|
|
"asset_type" "AssetType" NOT NULL,
|
|
"amount" DECIMAL(30,8) NOT NULL,
|
|
"balance_before" DECIMAL(30,8) NOT NULL,
|
|
"balance_after" DECIMAL(30,8) NOT NULL,
|
|
"counterparty_type" "CounterpartyType",
|
|
"counterparty_account_seq" TEXT,
|
|
"counterparty_user_id" TEXT,
|
|
"counterparty_system_id" TEXT,
|
|
"counterparty_pool_type" "PoolAccountType",
|
|
"counterparty_address" TEXT,
|
|
"reference_id" TEXT,
|
|
"reference_type" TEXT,
|
|
"tx_hash" TEXT,
|
|
"memo" TEXT,
|
|
"metadata" JSONB,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "system_account_transactions_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "pool_accounts" (
|
|
"id" TEXT NOT NULL,
|
|
"pool_type" "PoolAccountType" NOT NULL,
|
|
"name" TEXT NOT NULL,
|
|
"balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_inflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_outflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"target_burn" DECIMAL(30,8),
|
|
"remaining_burn" DECIMAL(30,8),
|
|
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
|
"description" TEXT,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updated_at" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "pool_accounts_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "pool_account_transactions" (
|
|
"id" TEXT NOT NULL,
|
|
"pool_account_id" TEXT NOT NULL,
|
|
"pool_type" "PoolAccountType" NOT NULL,
|
|
"transaction_type" "TransactionType" NOT NULL,
|
|
"amount" DECIMAL(30,8) NOT NULL,
|
|
"balance_before" DECIMAL(30,8) NOT NULL,
|
|
"balance_after" DECIMAL(30,8) NOT NULL,
|
|
"counterparty_type" "CounterpartyType",
|
|
"counterparty_account_seq" TEXT,
|
|
"counterparty_user_id" TEXT,
|
|
"counterparty_system_id" TEXT,
|
|
"counterparty_pool_type" "PoolAccountType",
|
|
"counterparty_address" TEXT,
|
|
"reference_id" TEXT,
|
|
"reference_type" TEXT,
|
|
"tx_hash" TEXT,
|
|
"memo" TEXT,
|
|
"metadata" JSONB,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "pool_account_transactions_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "user_wallets" (
|
|
"id" TEXT NOT NULL,
|
|
"account_sequence" TEXT NOT NULL,
|
|
"wallet_type" "UserWalletType" NOT NULL,
|
|
"balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"frozen_balance" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_inflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"total_outflow" DECIMAL(30,8) NOT NULL DEFAULT 0,
|
|
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updated_at" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "user_wallets_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "user_wallet_transactions" (
|
|
"id" TEXT NOT NULL,
|
|
"user_wallet_id" TEXT NOT NULL,
|
|
"account_sequence" TEXT NOT NULL,
|
|
"wallet_type" "UserWalletType" NOT NULL,
|
|
"transaction_type" "TransactionType" NOT NULL,
|
|
"asset_type" "AssetType" NOT NULL,
|
|
"amount" DECIMAL(30,8) NOT NULL,
|
|
"balance_before" DECIMAL(30,8) NOT NULL,
|
|
"balance_after" DECIMAL(30,8) NOT NULL,
|
|
"counterparty_type" "CounterpartyType",
|
|
"counterparty_account_seq" TEXT,
|
|
"counterparty_user_id" TEXT,
|
|
"counterparty_system_id" TEXT,
|
|
"counterparty_pool_type" "PoolAccountType",
|
|
"counterparty_address" TEXT,
|
|
"reference_id" TEXT,
|
|
"reference_type" TEXT,
|
|
"tx_hash" TEXT,
|
|
"memo" TEXT,
|
|
"metadata" JSONB,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "user_wallet_transactions_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "fee_configs" (
|
|
"id" TEXT NOT NULL,
|
|
"fee_type" TEXT NOT NULL,
|
|
"fee_rate" DECIMAL(10,6) NOT NULL,
|
|
"min_fee" DECIMAL(30,8) NOT NULL,
|
|
"max_fee" DECIMAL(30,8),
|
|
"headquarters_rate" DECIMAL(10,6) NOT NULL,
|
|
"operation_rate" DECIMAL(10,6) NOT NULL,
|
|
"province_rate" DECIMAL(10,6) NOT NULL,
|
|
"city_rate" DECIMAL(10,6) NOT NULL,
|
|
"is_active" BOOLEAN NOT NULL DEFAULT true,
|
|
"description" TEXT,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
"updated_at" TIMESTAMP(3) NOT NULL,
|
|
|
|
CONSTRAINT "fee_configs_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "outbox_events" (
|
|
"id" TEXT NOT NULL,
|
|
"aggregate_type" TEXT NOT NULL,
|
|
"aggregate_id" TEXT NOT NULL,
|
|
"event_type" TEXT NOT NULL,
|
|
"payload" JSONB NOT NULL,
|
|
"topic" TEXT NOT NULL DEFAULT 'mining-wallet.events',
|
|
"key" TEXT,
|
|
"status" "OutboxStatus" NOT NULL DEFAULT 'PENDING',
|
|
"retry_count" INTEGER NOT NULL DEFAULT 0,
|
|
"max_retries" INTEGER NOT NULL DEFAULT 10,
|
|
"last_error" TEXT,
|
|
"published_at" TIMESTAMP(3),
|
|
"next_retry_at" TIMESTAMP(3),
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "outbox_events_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "processed_events" (
|
|
"id" TEXT NOT NULL,
|
|
"event_id" TEXT NOT NULL,
|
|
"event_type" TEXT NOT NULL,
|
|
"source_service" TEXT NOT NULL,
|
|
"processed_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "processed_events_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateTable
|
|
CREATE TABLE "audit_logs" (
|
|
"id" TEXT NOT NULL,
|
|
"operator_id" TEXT NOT NULL,
|
|
"operator_type" TEXT NOT NULL,
|
|
"action" TEXT NOT NULL,
|
|
"resource" TEXT NOT NULL,
|
|
"resource_id" TEXT,
|
|
"old_value" JSONB,
|
|
"new_value" JSONB,
|
|
"ip_address" TEXT,
|
|
"user_agent" TEXT,
|
|
"created_at" TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
|
|
CONSTRAINT "audit_logs_pkey" PRIMARY KEY ("id")
|
|
);
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "provinces_code_key" ON "provinces"("code");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "provinces_code_idx" ON "provinces"("code");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "cities_code_key" ON "cities"("code");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "cities_province_id_idx" ON "cities"("province_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "cities_code_idx" ON "cities"("code");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "user_region_mappings_account_sequence_key" ON "user_region_mappings"("account_sequence");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_region_mappings_city_id_idx" ON "user_region_mappings"("city_id");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "system_accounts_code_key" ON "system_accounts"("code");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_accounts_account_type_idx" ON "system_accounts"("account_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_accounts_province_id_idx" ON "system_accounts"("province_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_accounts_city_id_idx" ON "system_accounts"("city_id");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "system_accounts_account_type_province_id_city_id_key" ON "system_accounts"("account_type", "province_id", "city_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_system_account_id_created_at_idx" ON "system_account_transactions"("system_account_id", "created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_transaction_type_idx" ON "system_account_transactions"("transaction_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_counterparty_account_seq_idx" ON "system_account_transactions"("counterparty_account_seq");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_counterparty_user_id_idx" ON "system_account_transactions"("counterparty_user_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_reference_id_idx" ON "system_account_transactions"("reference_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "system_account_transactions_created_at_idx" ON "system_account_transactions"("created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "pool_accounts_pool_type_key" ON "pool_accounts"("pool_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_accounts_pool_type_idx" ON "pool_accounts"("pool_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_pool_account_id_created_at_idx" ON "pool_account_transactions"("pool_account_id", "created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_pool_type_transaction_type_idx" ON "pool_account_transactions"("pool_type", "transaction_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_counterparty_account_seq_idx" ON "pool_account_transactions"("counterparty_account_seq");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_counterparty_user_id_idx" ON "pool_account_transactions"("counterparty_user_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_reference_id_idx" ON "pool_account_transactions"("reference_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "pool_account_transactions_created_at_idx" ON "pool_account_transactions"("created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallets_account_sequence_idx" ON "user_wallets"("account_sequence");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallets_wallet_type_idx" ON "user_wallets"("wallet_type");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "user_wallets_account_sequence_wallet_type_key" ON "user_wallets"("account_sequence", "wallet_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_user_wallet_id_created_at_idx" ON "user_wallet_transactions"("user_wallet_id", "created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_account_sequence_wallet_type_idx" ON "user_wallet_transactions"("account_sequence", "wallet_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_transaction_type_idx" ON "user_wallet_transactions"("transaction_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_counterparty_account_seq_idx" ON "user_wallet_transactions"("counterparty_account_seq");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_counterparty_user_id_idx" ON "user_wallet_transactions"("counterparty_user_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_reference_id_idx" ON "user_wallet_transactions"("reference_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "user_wallet_transactions_created_at_idx" ON "user_wallet_transactions"("created_at" DESC);
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "fee_configs_fee_type_key" ON "fee_configs"("fee_type");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "outbox_events_status_idx" ON "outbox_events"("status");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "outbox_events_next_retry_at_idx" ON "outbox_events"("next_retry_at");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "outbox_events_created_at_idx" ON "outbox_events"("created_at");
|
|
|
|
-- CreateIndex
|
|
CREATE UNIQUE INDEX "processed_events_event_id_key" ON "processed_events"("event_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "processed_events_source_service_idx" ON "processed_events"("source_service");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "processed_events_processed_at_idx" ON "processed_events"("processed_at");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "audit_logs_operator_id_idx" ON "audit_logs"("operator_id");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "audit_logs_action_idx" ON "audit_logs"("action");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "audit_logs_resource_idx" ON "audit_logs"("resource");
|
|
|
|
-- CreateIndex
|
|
CREATE INDEX "audit_logs_created_at_idx" ON "audit_logs"("created_at" DESC);
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "cities" ADD CONSTRAINT "cities_province_id_fkey" FOREIGN KEY ("province_id") REFERENCES "provinces"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "user_region_mappings" ADD CONSTRAINT "user_region_mappings_city_id_fkey" FOREIGN KEY ("city_id") REFERENCES "cities"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "system_accounts" ADD CONSTRAINT "system_accounts_province_id_fkey" FOREIGN KEY ("province_id") REFERENCES "provinces"("id") ON DELETE SET NULL ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "system_accounts" ADD CONSTRAINT "system_accounts_city_id_fkey" FOREIGN KEY ("city_id") REFERENCES "cities"("id") ON DELETE SET NULL ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "system_account_transactions" ADD CONSTRAINT "system_account_transactions_system_account_id_fkey" FOREIGN KEY ("system_account_id") REFERENCES "system_accounts"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "pool_account_transactions" ADD CONSTRAINT "pool_account_transactions_pool_account_id_fkey" FOREIGN KEY ("pool_account_id") REFERENCES "pool_accounts"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|
|
|
|
-- AddForeignKey
|
|
ALTER TABLE "user_wallet_transactions" ADD CONSTRAINT "user_wallet_transactions_user_wallet_id_fkey" FOREIGN KEY ("user_wallet_id") REFERENCES "user_wallets"("id") ON DELETE RESTRICT ON UPDATE CASCADE;
|