Files
peipei-backend/play-admin/src/main/resources/db/migration/V24__earnings_adjustments.sql

51 lines
3.3 KiB
SQL
Raw 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.

-- Earnings adjustments: introduce generic adjustment header table + source identity for earnings lines.
-- 1) Extend ledger to support non-order sources (e.g. admin adjustments / rewards / punishments).
-- We keep order_id for ORDER source for backward compatibility, but allow it to be NULL for adjustment lines.
-- Drop legacy uniqueness keyed by order_id, since order_id can now be NULL and we want uniqueness by source identity.
ALTER TABLE `play_earnings_line`
DROP INDEX `uk_tenant_order_clerk_type`;
ALTER TABLE `play_earnings_line`
MODIFY COLUMN `order_id` varchar(32) NULL COMMENT '订单IDsource_type=ORDER 时必填)',
ADD COLUMN `source_type` varchar(16) NOT NULL DEFAULT 'ORDER' COMMENT '来源类型ORDER/ADJUSTMENT' AFTER `order_id`,
ADD COLUMN `source_id` varchar(32) DEFAULT NULL COMMENT '来源IDsource_type=ORDER 时等于 order_idsource_type=ADJUSTMENT 时等于 adjustment_id' AFTER `source_type`;
-- Backfill existing rows to ORDER source.
UPDATE `play_earnings_line`
SET `source_id` = `order_id`
WHERE (`source_id` IS NULL)
AND `order_id` IS NOT NULL
AND `deleted` = 0;
-- New uniqueness: one line per source identity per clerk/type (ignoring logical delete).
ALTER TABLE `play_earnings_line`
ADD UNIQUE KEY `uk_tenant_source_clerk_type` (`tenant_id`, `source_type`, `source_id`, `clerk_id`, `earning_type`, `deleted`);
-- 2) Adjustment header table (idempotent, async lifecycle).
CREATE TABLE IF NOT EXISTS `play_earnings_line_adjustment` (
`id` varchar(32) NOT NULL COMMENT 'UUID',
`tenant_id` varchar(32) NOT NULL COMMENT '租户ID',
`clerk_id` varchar(32) NOT NULL COMMENT '店员ID',
`amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '调整金额可正可负不允许0',
`reason_type` varchar(32) NOT NULL COMMENT '原因类型Enum, hard-coded for now',
`reason_description` varchar(512) NOT NULL COMMENT '原因描述(操作时输入)',
`status` varchar(16) NOT NULL DEFAULT 'PROCESSING' COMMENT '状态PROCESSING/APPLIED/FAILED',
`idempotency_key` varchar(64) DEFAULT NULL COMMENT '幂等Keytenant范围内唯一为空则不幂等',
`request_hash` varchar(64) NOT NULL DEFAULT '' COMMENT '请求摘要用于检测同key不同body',
`effective_time` datetime NOT NULL COMMENT '生效时间(用于统计窗口;默认 now',
`applied_time` datetime DEFAULT NULL COMMENT '落账完成时间',
`failure_reason` varchar(512) DEFAULT NULL COMMENT '失败原因FAILED 时)',
`created_by` varchar(32) DEFAULT NULL,
`created_time` datetime DEFAULT CURRENT_TIMESTAMP,
`updated_by` varchar(32) DEFAULT NULL,
`updated_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`deleted` tinyint(1) NOT NULL DEFAULT '0' COMMENT '逻辑删除 1已删除 0未删除',
`version` int NOT NULL DEFAULT '1' COMMENT '数据版本',
PRIMARY KEY (`id`) USING BTREE,
UNIQUE KEY `uk_tenant_idempotency` (`tenant_id`, `idempotency_key`, `deleted`) USING BTREE,
KEY `idx_adjustment_tenant_clerk_time` (`tenant_id`, `clerk_id`, `effective_time`) USING BTREE,
KEY `idx_adjustment_tenant_status` (`tenant_id`, `status`) USING BTREE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci ROW_FORMAT=DYNAMIC COMMENT='收益调整Reward/Punishment/Correction统一抽象';