Files
junhong_cmp_fiber/migrations/000006_refactor_iot_models_architecture.down.sql
huang 2150fb6ab9 重构:完善 IoT 模型架构规范和数据库设计
- 完善 GORM 模型规范:货币字段使用 int64(分为单位)、JSONB 字段规范、模型结构规范
- 修复所有 IoT 模型的架构违规问题
- 更新 CLAUDE.md 开发指南,补充完整的数据库设计规范和模型示例
- 添加数据库迁移脚本(000006)用于架构重构
- 归档 OpenSpec 变更文档(2026-01-12-fix-iot-models-violations)

Co-Authored-By: Claude Sonnet 4.5 <noreply@anthropic.com>
2026-01-12 17:43:12 +08:00

252 lines
13 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.
-- IoT 模型架构重构回滚脚本
-- 创建时间: 2026-01-12
-- 说明: 回滚所有架构重构变更
-- 1. 恢复唯一索引(移除软删除支持)
-- 2. 恢复金额字段为 DECIMAL 类型
-- 3. 删除软删除字段和审计字段
-- 4. 恢复表名为复数形式
-- ========================================
-- 阶段 1: 恢复唯一约束(移除软删除支持)
-- ========================================
-- 1.1 运营商表
DROP INDEX IF EXISTS idx_carrier_code;
ALTER TABLE tb_carrier ADD CONSTRAINT carriers_carrier_code_key UNIQUE (carrier_code);
-- 1.2 IoT 卡表
DROP INDEX IF EXISTS idx_iot_card_iccid;
ALTER TABLE tb_iot_card ADD CONSTRAINT iot_cards_iccid_key UNIQUE (iccid);
-- 1.3 设备表
DROP INDEX IF EXISTS idx_device_no;
ALTER TABLE tb_device ADD CONSTRAINT devices_device_no_key UNIQUE (device_no);
-- 1.4 号卡表
DROP INDEX IF EXISTS idx_number_card_code;
ALTER TABLE tb_number_card ADD CONSTRAINT number_cards_virtual_product_code_key UNIQUE (virtual_product_code);
-- 1.5 套餐系列表
DROP INDEX IF EXISTS idx_package_series_code;
ALTER TABLE tb_package_series ADD CONSTRAINT package_series_series_code_key UNIQUE (series_code);
-- 1.6 套餐表
DROP INDEX IF EXISTS idx_package_code;
ALTER TABLE tb_package ADD CONSTRAINT packages_package_code_key UNIQUE (package_code);
-- 1.7 代理套餐分配表
DROP INDEX IF EXISTS idx_agent_package_allocation_agent_package;
ALTER TABLE tb_agent_package_allocation ADD CONSTRAINT uk_agent_package UNIQUE (agent_id, package_id);
-- 1.8 设备-SIM绑定表跳过保持原样
-- 1.9 订单表
DROP INDEX IF EXISTS idx_order_no;
ALTER TABLE tb_order ADD CONSTRAINT orders_order_no_key UNIQUE (order_no);
-- 1.10 轮询配置表
DROP INDEX IF EXISTS idx_polling_config_name;
ALTER TABLE tb_polling_config ADD CONSTRAINT polling_configs_config_name_key UNIQUE (config_name);
-- 1.11 代理层级表
DROP INDEX IF EXISTS idx_agent_hierarchy_agent;
ALTER TABLE tb_agent_hierarchy ADD CONSTRAINT agent_hierarchies_agent_id_key UNIQUE (agent_id);
-- 1.12 组合分佣条件表
DROP INDEX IF EXISTS idx_commission_combined_rule;
ALTER TABLE tb_commission_combined_condition ADD CONSTRAINT commission_combined_conditions_rule_id_key UNIQUE (rule_id);
-- 1.13 分佣模板表
DROP INDEX IF EXISTS idx_commission_template_name;
ALTER TABLE tb_commission_template ADD CONSTRAINT commission_templates_template_name_key UNIQUE (template_name);
-- 1.14 运营商结算表
DROP INDEX IF EXISTS idx_carrier_settlement_record;
ALTER TABLE tb_carrier_settlement ADD CONSTRAINT carrier_settlements_commission_record_id_key UNIQUE (commission_record_id);
-- 1.15 开发能力配置表
DROP INDEX IF EXISTS idx_dev_capability_app;
ALTER TABLE tb_dev_capability_config ADD CONSTRAINT dev_capability_configs_app_id_key UNIQUE (app_id);
-- ========================================
-- 阶段 2: 恢复金额字段为 DECIMAL 类型(分 / 100 = 元)
-- ========================================
-- 2.1 IoT 卡表
ALTER TABLE tb_iot_card
ALTER COLUMN cost_price TYPE DECIMAL(10,2) USING (cost_price / 100.0)::DECIMAL(10,2),
ALTER COLUMN distribute_price TYPE DECIMAL(10,2) USING (distribute_price / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_iot_card.cost_price IS '成本价(元)';
COMMENT ON COLUMN tb_iot_card.distribute_price IS '分销价(元)';
-- 2.2 号卡表
ALTER TABLE tb_number_card
ALTER COLUMN price TYPE DECIMAL(10,2) USING (price / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_number_card.price IS '价格(元)';
-- 2.3 套餐表
ALTER TABLE tb_package
ALTER COLUMN price TYPE DECIMAL(10,2) USING (price / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_package.price IS '套餐价格(元)';
-- 2.4 代理套餐分配表
ALTER TABLE tb_agent_package_allocation
ALTER COLUMN cost_price TYPE DECIMAL(10,2) USING (cost_price / 100.0)::DECIMAL(10,2),
ALTER COLUMN retail_price TYPE DECIMAL(10,2) USING (retail_price / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_agent_package_allocation.cost_price IS '成本价(元)';
COMMENT ON COLUMN tb_agent_package_allocation.retail_price IS '零售价(元)';
-- 2.5 订单表
ALTER TABLE tb_order
ALTER COLUMN amount TYPE DECIMAL(10,2) USING (amount / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_order.amount IS '订单金额(元)';
-- 2.6 分佣规则表
ALTER TABLE tb_commission_rule
ALTER COLUMN commission_value TYPE DECIMAL(10,2) USING (commission_value / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_rule.commission_value IS '分佣值(元或百分比)';
-- 2.7 阶梯分佣配置表
ALTER TABLE tb_commission_ladder
ALTER COLUMN commission_value TYPE DECIMAL(10,2) USING (commission_value / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_ladder.commission_value IS '分佣值(元或百分比)';
-- 2.8 组合分佣条件表
ALTER TABLE tb_commission_combined_condition
ALTER COLUMN one_time_commission_value TYPE DECIMAL(10,2) USING (one_time_commission_value / 100.0)::DECIMAL(10,2),
ALTER COLUMN long_term_commission_value TYPE DECIMAL(10,2) USING (long_term_commission_value / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_combined_condition.one_time_commission_value IS '一次性分佣值(元或百分比)';
COMMENT ON COLUMN tb_commission_combined_condition.long_term_commission_value IS '长期分佣值(元或百分比)';
-- 2.9 分佣记录表
ALTER TABLE tb_commission_record
ALTER COLUMN amount TYPE DECIMAL(10,2) USING (amount / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_record.amount IS '分佣金额(元)';
-- 2.10 分佣模板表
ALTER TABLE tb_commission_template
ALTER COLUMN commission_value TYPE DECIMAL(10,2) USING (commission_value / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_template.commission_value IS '分佣值(元或百分比)';
-- 2.11 运营商结算表
ALTER TABLE tb_carrier_settlement
ALTER COLUMN settlement_amount TYPE DECIMAL(10,2) USING (settlement_amount / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_carrier_settlement.settlement_amount IS '结算金额(元)';
-- 2.12 佣金提现申请表
ALTER TABLE tb_commission_withdrawal_request
ALTER COLUMN amount TYPE DECIMAL(10,2) USING (amount / 100.0)::DECIMAL(10,2),
ALTER COLUMN fee TYPE DECIMAL(10,2) USING (fee / 100.0)::DECIMAL(10,2),
ALTER COLUMN actual_amount TYPE DECIMAL(10,2) USING (actual_amount / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_withdrawal_request.amount IS '提现金额(元)';
COMMENT ON COLUMN tb_commission_withdrawal_request.fee IS '手续费(元)';
COMMENT ON COLUMN tb_commission_withdrawal_request.actual_amount IS '实际到账金额(元)';
-- 2.13 佣金提现设置表
ALTER TABLE tb_commission_withdrawal_setting
ALTER COLUMN min_withdrawal_amount TYPE DECIMAL(10,2) USING (min_withdrawal_amount / 100.0)::DECIMAL(10,2);
COMMENT ON COLUMN tb_commission_withdrawal_setting.min_withdrawal_amount IS '最低提现金额(元)';
-- ========================================
-- 阶段 3: 删除软删除字段和审计字段
-- ========================================
ALTER TABLE tb_carrier DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_iot_card DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_device DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_number_card DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_package_series DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_package DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_agent_package_allocation DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_device_sim_binding DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_order DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_package_usage DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_polling_config DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
-- 注意: tb_data_usage_record 没有添加这些字段,所以不需要删除
ALTER TABLE tb_agent_hierarchy DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_rule DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_ladder DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_combined_condition DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_record DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_approval DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_template DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_carrier_settlement DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_withdrawal_request DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_commission_withdrawal_setting DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_payment_merchant_setting DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_dev_capability_config DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
ALTER TABLE tb_card_replacement_request DROP COLUMN deleted_at, DROP COLUMN creator, DROP COLUMN updater;
-- ========================================
-- 阶段 4: 恢复表名为复数形式
-- ========================================
ALTER TABLE tb_carrier RENAME TO carriers;
ALTER TABLE tb_iot_card RENAME TO iot_cards;
ALTER TABLE tb_device RENAME TO devices;
ALTER TABLE tb_number_card RENAME TO number_cards;
ALTER TABLE tb_package_series RENAME TO package_series;
ALTER TABLE tb_package RENAME TO packages;
ALTER TABLE tb_agent_package_allocation RENAME TO agent_package_allocations;
ALTER TABLE tb_device_sim_binding RENAME TO device_sim_bindings;
ALTER TABLE tb_order RENAME TO orders;
ALTER TABLE tb_package_usage RENAME TO package_usages;
ALTER TABLE tb_polling_config RENAME TO polling_configs;
ALTER TABLE tb_data_usage_record RENAME TO data_usage_records;
ALTER TABLE tb_agent_hierarchy RENAME TO agent_hierarchies;
ALTER TABLE tb_commission_rule RENAME TO commission_rules;
ALTER TABLE tb_commission_ladder RENAME TO commission_ladder;
ALTER TABLE tb_commission_combined_condition RENAME TO commission_combined_conditions;
ALTER TABLE tb_commission_record RENAME TO commission_records;
ALTER TABLE tb_commission_approval RENAME TO commission_approvals;
ALTER TABLE tb_commission_template RENAME TO commission_templates;
ALTER TABLE tb_carrier_settlement RENAME TO carrier_settlements;
ALTER TABLE tb_commission_withdrawal_request RENAME TO commission_withdrawal_requests;
ALTER TABLE tb_commission_withdrawal_setting RENAME TO commission_withdrawal_settings;
ALTER TABLE tb_payment_merchant_setting RENAME TO payment_merchant_settings;
ALTER TABLE tb_dev_capability_config RENAME TO dev_capability_configs;
ALTER TABLE tb_card_replacement_request RENAME TO card_replacement_requests;
-- ========================================
-- 阶段 5: 恢复表注释
-- ========================================
COMMENT ON TABLE carriers IS '运营商表';
COMMENT ON TABLE iot_cards IS 'IoT 卡表(物联网卡/流量卡)';
COMMENT ON TABLE devices IS '设备表(可容纳1-4张SIM卡)';
COMMENT ON TABLE number_cards IS '号卡表(虚拟商品)';
COMMENT ON TABLE package_series IS '套餐系列表';
COMMENT ON TABLE packages IS '套餐表';
COMMENT ON TABLE agent_package_allocations IS '代理套餐分配表';
COMMENT ON TABLE device_sim_bindings IS '设备-SIM卡绑定表';
COMMENT ON TABLE orders IS '订单表';
COMMENT ON TABLE package_usages IS '套餐使用表';
COMMENT ON TABLE polling_configs IS '轮询配置表';
COMMENT ON TABLE data_usage_records IS '流量使用记录表';
COMMENT ON TABLE agent_hierarchies IS '代理层级关系表';
COMMENT ON TABLE commission_rules IS '分佣规则表';
COMMENT ON TABLE commission_ladder IS '阶梯分佣配置表';
COMMENT ON TABLE commission_combined_conditions IS '组合分佣条件表';
COMMENT ON TABLE commission_records IS '分佣记录表';
COMMENT ON TABLE commission_approvals IS '分佣审批表';
COMMENT ON TABLE commission_templates IS '分佣模板表';
COMMENT ON TABLE carrier_settlements IS '号卡运营商结算表';
COMMENT ON TABLE commission_withdrawal_requests IS '佣金提现申请表';
COMMENT ON TABLE commission_withdrawal_settings IS '佣金提现设置表';
COMMENT ON TABLE payment_merchant_settings IS '收款商户设置表';
COMMENT ON TABLE dev_capability_configs IS '开发能力配置表';
COMMENT ON TABLE card_replacement_requests IS '换卡申请表';