CREATE OR REPLACE PROCEDURE "public"."pro_hot_water_run_param"("floor_id_in" varchar, "floor_id_1_in" varchar, "floor_id_2_in" varchar, "cur_time_in" varchar) AS $BODY$ DECLARE -- 变量声明(保持原有结构,默认值优化) temp_set_hot_pump_one NUMERIC(24,2) := 0; temp_real_hot_pump_one NUMERIC(24,2) := 0; status_switch_hot_pump_one INT := 0; status_run_hot_pump_one INT := 0; temp_set_hot_pump_two NUMERIC(24,2) := 0; temp_real_hot_pump_two NUMERIC(24,2) := 0; status_switch_hot_pump_two INT := 0; status_run_hot_pump_two INT := 0; temp_set_hot_pump_three NUMERIC(24,2) := 0; temp_real_hot_pump_three NUMERIC(24,2) := 0; status_switch_hot_pump_three INT := 0; status_run_hot_pump_three INT := 0; temp_set_hot_pump_four NUMERIC(24,2) := 0; temp_real_hot_pump_four NUMERIC(24,2) := 0; status_switch_hot_pump_four INT := 0; status_run_hot_pump_four INT := 0; pres_set_supply_pump_area_one NUMERIC(24,2) := 0; pres_real_supply_pump_area_one NUMERIC(24,2) := 0; status_run_supply_pump_one INT := 0; status_run_supply_pump_two INT := 0; pres_set_supply_pump_area_two NUMERIC(24,2) := 0; pres_real_supply_pump_area_two NUMERIC(24,2) := 0; status_run_supply_pump_three INT := 0; status_run_supply_pump_four INT := 0; level_water_tank_one NUMERIC(24,2) := 0; level_water_tank_two NUMERIC(24,2) := 0; is_exits INT := 0; register_address VARCHAR(50); other_name VARCHAR(50); value NUMERIC(24,2); mt_num varchar(20); -- 游标1:中区/中厨 base_param_1 CURSOR FOR select cpm.mt_num::VARCHAR, COALESCE(MAX(cpm.cur_value), 0)::NUMERIC(24,2) from collection_params_manage cpm left join device_ledger dl on cpm.device_ledger_id = dl.id left join cpm_space_relation csr on cpm.id = csr.cpm_id left join house_info hi on csr.house_id = hi.id where csr.floor_id = floor_id_2_in and cpm.system_type = '1' and cpm.is_use = 0 and hi.house_name is not null AND TO_CHAR(cpm.cur_time, 'YYYY-MM-DD HH24') = cur_time_in GROUP BY cpm.cur_time::DATE, cpm.mt_num; -- 游标2:高区/裙楼 base_param_2 CURSOR FOR select cpm.other_name::VARCHAR, cpm.mt_num::VARCHAR, COALESCE(MAX(cpm.cur_value), 0)::NUMERIC(24,2) from collection_params_manage cpm left join device_ledger dl on cpm.device_ledger_id = dl.id left join cpm_space_relation csr on cpm.id = csr.cpm_id left join house_info hi on csr.house_id = hi.id where csr.floor_id = floor_id_1_in and cpm.system_type = '1' and cpm.is_use = 0 and hi.house_name is not null AND TO_CHAR(cpm.cur_time, 'YYYY-MM-DD HH24') = cur_time_in GROUP BY cpm.other_name::VARCHAR, cpm.cur_time::DATE, cpm.mt_num; BEGIN -- ------------------------------ -- 4. 遍历游标获取寄存器参数(严格关闭游标)高区/裙楼 -- ------------------------------ OPEN base_param_1; BEGIN -- 游标操作的异常处理块 LOOP FETCH NEXT FROM base_param_1 INTO register_address, value; EXIT WHEN NOT FOUND; -- 根据寄存器地址映射参数值 case WHEN register_address in ('1VD04000','2VD04000') THEN pres_set_supply_pump_area_two := value; WHEN register_address in ('1VD01500','2VD01500') THEN pres_real_supply_pump_area_two := value; WHEN register_address in ('1I00007','2I00007') THEN status_run_supply_pump_three := value; WHEN register_address in ('1I00012','2I00012') THEN status_run_supply_pump_four := value; WHEN register_address in ('1VD09200','2VD09200') THEN level_water_tank_two := value; ELSE -- 记录未匹配的寄存器地址(新增) RAISE NOTICE '未匹配的寄存器地址(设备:%): %', floor_id_1_in, register_address; END CASE; END LOOP; EXCEPTION WHEN OTHERS THEN -- 游标异常时记录错误 RAISE NOTICE '游标遍历失败(设备:%): %', floor_id_1_in, SQLERRM; END; CLOSE base_param_1; -- 确保游标最终关闭 RAISE NOTICE '关闭游标'; -- ------------------------------ -- 4. 遍历游标获取寄存器参数(严格关闭游标)中区/中厨 -- ------------------------------ OPEN base_param_2; BEGIN LOOP FETCH NEXT FROM base_param_2 INTO other_name, register_address, value; EXIT WHEN NOT FOUND; CASE -- 合并判断条件(推荐写法) WHEN other_name in ('3号热泵温度设置','1号热泵温度设置') and register_address IN ('1', '3') THEN temp_set_hot_pump_one := value; WHEN other_name in ('3号热泵实际温度','1号热泵实际温度') and register_address IN ('1', '3') THEN temp_real_hot_pump_one := value; WHEN other_name in ('3号热泵启停控制','1号热泵启停控制') and register_address IN ('1', '3') THEN status_switch_hot_pump_one := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('3号热泵电流1','1号热泵电流1') and register_address IN ('1', '3') THEN temp_real_hot_pump_one := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('4号热泵温度设置','2号热泵温度设置') and register_address IN ('2', '4') THEN temp_set_hot_pump_two := value; WHEN other_name in ('4号热泵实际温度','2号热泵实际温度') and register_address IN ('2', '4') THEN temp_real_hot_pump_two := value; WHEN other_name in ('4号热泵启停控制','2号热泵启停控制') and register_address IN ('2', '4') THEN status_switch_hot_pump_two := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('4号热泵电流1','2号热泵电流1') and register_address IN ('2', '4') THEN temp_real_hot_pump_two := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('5号热泵温度设置') and register_address IN ('5') THEN temp_set_hot_pump_three := value; WHEN other_name in ('5号热泵实际温度') and register_address IN ('5') THEN temp_real_hot_pump_three := value; WHEN other_name in ('5号热泵启停控制') and register_address IN ('5') THEN status_switch_hot_pump_three := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('5号热泵电流1') and register_address IN ('5') THEN temp_real_hot_pump_three := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('6号热泵温度设置') and register_address IN ('6') THEN temp_set_hot_pump_four := value; WHEN other_name in ('6号热泵实际温度') and register_address IN ('6') THEN temp_real_hot_pump_four := value; WHEN other_name in ('6号热泵启停控制') and register_address IN ('6') THEN status_switch_hot_pump_four := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN other_name in ('6号热泵电流1') and register_address IN ('6') THEN temp_real_hot_pump_four := CASE WHEN value > 1 THEN 1 ELSE 0 END; WHEN register_address IN ('1VD07000', '2VD07000') THEN pres_set_supply_pump_area_one := value; WHEN register_address IN ('1VD01800', '2VD01800') THEN pres_real_supply_pump_area_one := value; WHEN register_address IN ('1I00001', '2I00001') THEN status_run_supply_pump_one := value; WHEN register_address IN ('1I00004', '2I00004') THEN status_run_supply_pump_two := value; WHEN register_address IN ('2VD06100', '1VD06100') THEN level_water_tank_one := value; ELSE RAISE NOTICE '设备类型或寄存器地址不匹配(设备:%): %', floor_id_2_in, register_address; END CASE; END LOOP; EXCEPTION WHEN OTHERS THEN RAISE NOTICE '游标遍历失败(设备:%): %', floor_id_2_in, SQLERRM; END; CLOSE base_param_2; -- 确保游标最终关闭 RAISE NOTICE '关闭游标'; -- ------------------------------ -- 5. 插入历史数据(处理唯一约束冲突) -- ------------------------------ SELECT COUNT(1) INTO is_exits FROM report_hot_water_param_his WHERE cur_time = cur_time_in AND floor_id = floor_id_in; IF is_exits = 0 THEN INSERT INTO public.report_hot_water_param_his ( id, floor_id, cur_date, cur_time, temp_set_hot_pump_one, temp_real_hot_pump_one, status_switch_hot_pump_one, status_run_hot_pump_one, temp_set_hot_pump_two, temp_real_hot_pump_two, status_switch_hot_pump_two, status_run_hot_pump_two, temp_set_hot_pump_three, temp_real_hot_pump_three, status_switch_hot_pump_three, status_run_hot_pump_three, temp_set_hot_pump_four, temp_real_hot_pump_four, status_switch_hot_pump_four, status_run_hot_pump_four, pres_set_supply_pump_area_one, pres_real_supply_pump_area_one, status_run_supply_pump_one, status_run_supply_pump_two, pres_set_supply_pump_area_two, pres_real_supply_pump_area_two, status_run_supply_pump_three, status_run_supply_pump_four, level_water_tank_one, level_water_tank_two ) VALUES ( uuid_generate_v1mc(), floor_id_in, LEFT(cur_time_in, 10)::DATE, cur_time_in, temp_set_hot_pump_one, temp_real_hot_pump_one, status_switch_hot_pump_one, status_run_hot_pump_one, temp_set_hot_pump_two, temp_real_hot_pump_two, status_switch_hot_pump_two, status_run_hot_pump_two, temp_set_hot_pump_three, temp_real_hot_pump_three, status_switch_hot_pump_three, status_run_hot_pump_three, temp_set_hot_pump_four, temp_real_hot_pump_four, status_switch_hot_pump_four, status_run_hot_pump_four, pres_set_supply_pump_area_one, pres_real_supply_pump_area_one, status_run_supply_pump_one, status_run_supply_pump_two, pres_set_supply_pump_area_two, pres_real_supply_pump_area_two, status_run_supply_pump_three, status_run_supply_pump_four, level_water_tank_one, level_water_tank_two ); END IF; EXCEPTION WHEN OTHERS THEN -- 主事务异常时,记录错误 RAISE NOTICE '存储过程执行失败(设备:%,时间:%): %', floor_id_in, cur_time_in, SQLERRM; END; $BODY$ LANGUAGE plpgsql