refactor(database): 更新序列同步脚本以使用主键最大值对齐

- 将序列对齐逻辑从表行数改为按主键列最大值+1设置NEXTVAL
- 修改sync_seq过程参数,增加主键列名参数支持精确对齐
- 使用all_sequences替代user_sequences实现跨schema兼容
- 添加grant_and_synonym过程为所有序列授权并创建公共同义词
- 更新所有27个DMS序列的调用方式,传入对应主键列名
- 改进错误输出格式,统一日志信息显示样式
- 完善注释文档,明确序列对齐和权限配置说明
master
zangch@mesnac.com 1 week ago
parent 1395c278f9
commit 42ae0d364e

@ -463,15 +463,17 @@ CREATE SEQUENCE "HAIWEI"."SEQ_DMS_REPAIR_WORK_ORDER"
INCREMENT BY 1
CACHE 20;
-- 序列对齐:按表当前行数 + 1 设置 NEXTVALOracle 11g 兼容方案)
-- ============================================
-- 序列对齐:按 MAX(主键列)+1 设置 NEXTVALOracle 11g 兼容方案)
-- ============================================
-- 实现思路:
-- 1) 读取表行数,目标值 = 行数 + 1
-- 2) 读取当前序列 last_number
-- 1) 读取表主键最大值,目标值 = MAX(pk)+1空表则为1
-- 2) 读取当前序列 last_number(使用 all_sequences 兼容跨 schema
-- 3) 若目标值 > last_number则临时修改 INCREMENT BY (差值),取一次 NEXTVAL最后再改回 1
-- 4) 若目标值 <= last_number则保持不变仅输出提示
DECLARE
PROCEDURE sync_seq(p_seq_name VARCHAR2, p_table_name VARCHAR2) IS
v_cnt NUMBER := 0;
PROCEDURE sync_seq(p_seq_name VARCHAR2, p_table_name VARCHAR2, p_pk_col VARCHAR2) IS
v_max_id NUMBER := 0;
v_last NUMBER := 0;
v_target NUMBER := 0;
v_diff NUMBER := 0;
@ -479,63 +481,129 @@ DECLARE
v_sql VARCHAR2(4000);
v_dummy NUMBER;
BEGIN
-- 表行数
v_sql := 'SELECT NVL(COUNT(*),0) FROM ' || p_table_name;
EXECUTE IMMEDIATE v_sql INTO v_cnt;
-- 取表主键最大值
v_sql := 'SELECT NVL(MAX(' || p_pk_col || '),0) FROM ' || p_table_name;
EXECUTE IMMEDIATE v_sql INTO v_max_id;
-- 取 sequence 名(去 schema 部分)用于 USER_SEQUENCES 查询
-- 取 sequence 名(去 schema 部分)用于 ALL_SEQUENCES 查询
v_seq_short := UPPER(REGEXP_SUBSTR(p_seq_name, '[^\.]+$'));
SELECT last_number INTO v_last FROM user_sequences WHERE sequence_name = v_seq_short;
SELECT last_number INTO v_last FROM all_sequences
WHERE sequence_name = v_seq_short AND sequence_owner = 'HAIWEI';
v_target := v_cnt + 1;
v_target := v_max_id + 1;
IF v_target > v_last THEN
v_diff := v_target - v_last;
EXECUTE IMMEDIATE 'ALTER SEQUENCE ' || p_seq_name || ' INCREMENT BY ' || v_diff;
EXECUTE IMMEDIATE 'SELECT ' || p_seq_name || '.NEXTVAL FROM DUAL' INTO v_dummy;
EXECUTE IMMEDIATE 'ALTER SEQUENCE ' || p_seq_name || ' INCREMENT BY 1';
DBMS_OUTPUT.PUT_LINE('SYNC ' || p_seq_name || ' TO ' || v_target || ' (TABLE ROWS=' || v_cnt || ')');
DBMS_OUTPUT.PUT_LINE('SYNC ' || p_seq_name || ' -> ' || v_target || ' (MAX_ID=' || v_max_id || ')');
ELSE
DBMS_OUTPUT.PUT_LINE('SKIP ' || p_seq_name || ' (TARGET ' || v_target || ' <= LAST ' || v_last || ')');
END IF;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('SYNC ' || p_seq_name || ' FAILED: ' || SQLERRM);
DBMS_OUTPUT.PUT_LINE('ERR ' || p_seq_name || ': ' || SQLERRM);
END;
PROCEDURE grant_and_synonym(p_seq_short VARCHAR2) IS
BEGIN
EXECUTE IMMEDIATE 'GRANT SELECT ON HAIWEI.' || p_seq_short || ' TO PUBLIC';
EXECUTE IMMEDIATE 'CREATE OR REPLACE PUBLIC SYNONYM ' || p_seq_short || ' FOR HAIWEI.' || p_seq_short;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('GRANT/SYN ' || p_seq_short || ' SKIP: ' || SQLERRM);
END;
BEGIN
sync_seq('HAIWEI.SEQ_DMS_INSPECT_PROJ', 'HAIWEI.DMS_BASE_INSPECT_PROJECT');
sync_seq('HAIWEI.SEQ_DMS_INSPECT_ROUTE', 'HAIWEI.DMS_BASE_INSPECT_ROUTE');
sync_seq('HAIWEI.SEQ_DMS_INSPECT_STD', 'HAIWEI.DMS_BASE_INSPECT_STANDARD');
sync_seq('HAIWEI.SEQ_DMS_INSPECT_RTE_DTL', 'HAIWEI.DMS_INSPECT_ROUTE_DETAIL');
sync_seq('HAIWEI.SEQ_DMS_LUBE_STD', 'HAIWEI.DMS_BASE_LUBE_STANDARD');
sync_seq('HAIWEI.SEQ_DMS_LUBE_STATION', 'HAIWEI.DMS_BASE_LUBE_STATION');
sync_seq('HAIWEI.SEQ_DMS_MAINT_PROJ', 'HAIWEI.DMS_BASE_MAINT_PROJECT');
sync_seq('HAIWEI.SEQ_DMS_MAINT_STD', 'HAIWEI.DMS_BASE_MAINT_STANDARD');
sync_seq('HAIWEI.SEQ_DMS_MAINT_STATION', 'HAIWEI.DMS_BASE_MAINT_STATION');
sync_seq('HAIWEI.SEQ_DMS_SHUT_REASON', 'HAIWEI.DMS_BASE_SHUT_REASON');
sync_seq('HAIWEI.SEQ_DMS_SHUT_TYPE', 'HAIWEI.DMS_BASE_SHUT_TYPE');
sync_seq('HAIWEI.SEQ_DMS_BILLS_FAULT_INSTANCE', 'HAIWEI.DMS_BILLS_FAULT_INSTANCE');
sync_seq('HAIWEI.SEQ_FAULT_INSTANCE_ACTIVITY', 'HAIWEI.DMS_FAULT_INSTANCE_ACTIVITY');
sync_seq('HAIWEI.SEQ_DMS_MAINT_INST', 'HAIWEI.DMS_BILLS_MAINT_INSTANCE');
sync_seq('HAIWEI.SEQ_DMS_MAINT_DETAIL', 'HAIWEI.DMS_BILLS_MAINT_DETAIL');
sync_seq('HAIWEI.SEQ_DMS_MAINT_DTL_PROJ', 'HAIWEI.DMS_BILLS_MAINT_DETAIL_PROJECT');
sync_seq('HAIWEI.SEQ_DMS_DISPATCH_PLAN', 'HAIWEI.DMS_DISPATCH_PLAN');
sync_seq('HAIWEI.SEQ_DMS_DISPATCH_MEMBER', 'HAIWEI.DMS_DISPATCH_MEMBER');
sync_seq('HAIWEI.SEQ_DMS_KNOWLEDGE_REPAIR', 'HAIWEI.DMS_KNOWLEDGE_REPAIR');
sync_seq('HAIWEI.SEQ_DMS_PLAN_INSPECT', 'HAIWEI.DMS_PLAN_INSPECT');
sync_seq('HAIWEI.SEQ_DMS_PLAN_MAINT', 'HAIWEI.DMS_PLAN_MAINT');
sync_seq('HAIWEI.SEQ_DMS_PLAN_MAINT_DETAIL', 'HAIWEI.DMS_PLAN_MAINT_DETAIL');
sync_seq('HAIWEI.SEQ_DMS_PLAN_REPAIR', 'HAIWEI.DMS_PLAN_REPAIR');
sync_seq('HAIWEI.SEQ_DMS_REPAIR_MATERIAL', 'HAIWEI.DMS_REPAIR_MATERIAL');
sync_seq('HAIWEI.SEQ_DMS_REPAIR_PROJECT', 'HAIWEI.DMS_REPAIR_PROJECT');
sync_seq('HAIWEI.SEQ_DMS_REPAIR_RECORD', 'HAIWEI.DMS_REPAIR_RECORD');
sync_seq('HAIWEI.SEQ_DMS_REPAIR_WORK_ORDER', 'HAIWEI.DMS_REPAIR_WORK_ORDER');
-- 1. 点检项目
sync_seq('HAIWEI.SEQ_DMS_INSPECT_PROJ', 'HAIWEI.DMS_BASE_INSPECT_PROJECT', 'INSPECT_PROJECT_ID');
-- 2. 点检路线
sync_seq('HAIWEI.SEQ_DMS_INSPECT_ROUTE', 'HAIWEI.DMS_BASE_INSPECT_ROUTE', 'INSPECT_ROUTE_ID');
-- 3. 点检标准
sync_seq('HAIWEI.SEQ_DMS_INSPECT_STD', 'HAIWEI.DMS_BASE_INSPECT_STANDARD', 'INSPECT_STANDARD_ID');
-- 4. 点检路线明细
sync_seq('HAIWEI.SEQ_DMS_INSPECT_RTE_DTL', 'HAIWEI.DMS_INSPECT_ROUTE_DETAIL', 'ROUTE_DETAIL_ID');
-- 5. 润滑标准
sync_seq('HAIWEI.SEQ_DMS_LUBE_STD', 'HAIWEI.DMS_BASE_LUBE_STANDARD', 'LUBE_STANDARD_ID');
-- 6. 润滑部位
sync_seq('HAIWEI.SEQ_DMS_LUBE_STATION', 'HAIWEI.DMS_BASE_LUBE_STATION', 'LUBE_STATION_ID');
-- 7. 保养项目
sync_seq('HAIWEI.SEQ_DMS_MAINT_PROJ', 'HAIWEI.DMS_BASE_MAINT_PROJECT', 'MAINT_PROJECT_ID');
-- 8. 保养标准
sync_seq('HAIWEI.SEQ_DMS_MAINT_STD', 'HAIWEI.DMS_BASE_MAINT_STANDARD', 'MAINT_STANDARD_ID');
-- 9. 保养部位
sync_seq('HAIWEI.SEQ_DMS_MAINT_STATION', 'HAIWEI.DMS_BASE_MAINT_STATION', 'MAINT_STATION_ID');
-- 10. 停机原因
sync_seq('HAIWEI.SEQ_DMS_SHUT_REASON', 'HAIWEI.DMS_BASE_SHUT_REASON', 'SHUT_REASON_ID');
-- 11. 停机类型
sync_seq('HAIWEI.SEQ_DMS_SHUT_TYPE', 'HAIWEI.DMS_BASE_SHUT_TYPE', 'SHUT_TYPE_ID');
-- 12. 故障工单
sync_seq('HAIWEI.SEQ_DMS_BILLS_FAULT_INSTANCE', 'HAIWEI.DMS_BILLS_FAULT_INSTANCE', 'REPAIR_INSTANCE_ID');
-- 13. 故障工单活动
sync_seq('HAIWEI.SEQ_FAULT_INSTANCE_ACTIVITY', 'HAIWEI.DMS_FAULT_INSTANCE_ACTIVITY', 'INSTANCE_ACTIVITY_ID');
-- 14. 保养工单
sync_seq('HAIWEI.SEQ_DMS_MAINT_INST', 'HAIWEI.DMS_BILLS_MAINT_INSTANCE', 'MAINT_INSTANCE_ID');
-- 15. 保养工单明细
sync_seq('HAIWEI.SEQ_DMS_MAINT_DETAIL', 'HAIWEI.DMS_BILLS_MAINT_DETAIL', 'BILLS_MAINT_DETAIL_ID');
-- 16. 保养明细项目
sync_seq('HAIWEI.SEQ_DMS_MAINT_DTL_PROJ', 'HAIWEI.DMS_BILLS_MAINT_DETAIL_PROJECT','MAINT_DETAIL_PROJECT_ID');
-- 17. 派工计划
sync_seq('HAIWEI.SEQ_DMS_DISPATCH_PLAN', 'HAIWEI.DMS_DISPATCH_PLAN', 'PLAN_ID');
-- 18. 派工成员
sync_seq('HAIWEI.SEQ_DMS_DISPATCH_MEMBER', 'HAIWEI.DMS_DISPATCH_MEMBER', 'MEMBER_ID');
-- 19. 维修知识库
sync_seq('HAIWEI.SEQ_DMS_KNOWLEDGE_REPAIR', 'HAIWEI.DMS_KNOWLEDGE_REPAIR', 'KNOWLEDGE_REPAIR_ID');
-- 20. 点检计划
sync_seq('HAIWEI.SEQ_DMS_PLAN_INSPECT', 'HAIWEI.DMS_PLAN_INSPECT', 'PLAN_INSPECT_ID');
-- 21. 保养计划
sync_seq('HAIWEI.SEQ_DMS_PLAN_MAINT', 'HAIWEI.DMS_PLAN_MAINT', 'PLAN_MAINT_ID');
-- 22. 保养计划明细
sync_seq('HAIWEI.SEQ_DMS_PLAN_MAINT_DETAIL', 'HAIWEI.DMS_PLAN_MAINT_DETAIL', 'PLAN_MAINT_DETAIL_ID');
-- 23. 检修计划
sync_seq('HAIWEI.SEQ_DMS_PLAN_REPAIR', 'HAIWEI.DMS_PLAN_REPAIR', 'PLAN_REPAIR_ID');
-- 24. 维修物料
sync_seq('HAIWEI.SEQ_DMS_REPAIR_MATERIAL', 'HAIWEI.DMS_REPAIR_MATERIAL', 'MATERIAL_ID');
-- 25. 维修项目
sync_seq('HAIWEI.SEQ_DMS_REPAIR_PROJECT', 'HAIWEI.DMS_REPAIR_PROJECT', 'PROJECT_ID');
-- 26. 维修记录
sync_seq('HAIWEI.SEQ_DMS_REPAIR_RECORD', 'HAIWEI.DMS_REPAIR_RECORD', 'RECORD_ID');
-- 27. 维修工单
sync_seq('HAIWEI.SEQ_DMS_REPAIR_WORK_ORDER', 'HAIWEI.DMS_REPAIR_WORK_ORDER', 'WORK_ORDER_ID');
-- 为所有序列授权 + 创建公共同义词(保证跨 schema 应用可用)
grant_and_synonym('SEQ_DMS_INSPECT_PROJ');
grant_and_synonym('SEQ_DMS_INSPECT_ROUTE');
grant_and_synonym('SEQ_DMS_INSPECT_STD');
grant_and_synonym('SEQ_DMS_INSPECT_RTE_DTL');
grant_and_synonym('SEQ_DMS_LUBE_STD');
grant_and_synonym('SEQ_DMS_LUBE_STATION');
grant_and_synonym('SEQ_DMS_MAINT_PROJ');
grant_and_synonym('SEQ_DMS_MAINT_STD');
grant_and_synonym('SEQ_DMS_MAINT_STATION');
grant_and_synonym('SEQ_DMS_SHUT_REASON');
grant_and_synonym('SEQ_DMS_SHUT_TYPE');
grant_and_synonym('SEQ_DMS_BILLS_FAULT_INSTANCE');
grant_and_synonym('SEQ_FAULT_INSTANCE_ACTIVITY');
grant_and_synonym('SEQ_DMS_MAINT_INST');
grant_and_synonym('SEQ_DMS_MAINT_DETAIL');
grant_and_synonym('SEQ_DMS_MAINT_DTL_PROJ');
grant_and_synonym('SEQ_DMS_DISPATCH_PLAN');
grant_and_synonym('SEQ_DMS_DISPATCH_MEMBER');
grant_and_synonym('SEQ_DMS_KNOWLEDGE_REPAIR');
grant_and_synonym('SEQ_DMS_PLAN_INSPECT');
grant_and_synonym('SEQ_DMS_PLAN_MAINT');
grant_and_synonym('SEQ_DMS_PLAN_MAINT_DETAIL');
grant_and_synonym('SEQ_DMS_PLAN_REPAIR');
grant_and_synonym('SEQ_DMS_REPAIR_MATERIAL');
grant_and_synonym('SEQ_DMS_REPAIR_PROJECT');
grant_and_synonym('SEQ_DMS_REPAIR_RECORD');
grant_and_synonym('SEQ_DMS_REPAIR_WORK_ORDER');
END;
/
-- ============================================
-- 执行完成提示
-- ============================================
-- 共创建 27 个序列
-- 如需验证,可执行:
-- SELECT SEQUENCE_NAME FROM USER_SEQUENCES WHERE SEQUENCE_NAME LIKE 'SEQ_DMS%' OR SEQUENCE_NAME LIKE 'SEQ_FAULT%';
-- 共创建 27 个序列,已按 MAX(主键)+1 对齐,已授权+同义词
-- 验证:
-- SELECT SEQUENCE_NAME, LAST_NUMBER FROM ALL_SEQUENCES WHERE SEQUENCE_OWNER='HAIWEI' AND (SEQUENCE_NAME LIKE 'SEQ_DMS%' OR SEQUENCE_NAME LIKE 'SEQ_FAULT%');

Loading…
Cancel
Save