-- DROP PROCEDURE public.pro_heating_run_param(varchar); CREATE OR REPLACE PROCEDURE public.pro_heating_run_param(IN cur_time_in character varying) LANGUAGE plpgsql AS $procedure$ DECLARE -- 变量声明(保持原有结构,默认值优化) cur_status_boiler_one numeric(24, 2) := 0 ; temp_out_boiler_one numeric(24,2) :=0; temp_in_boiler_one numeric(24,2) :=0; temp_water_boiler_one numeric(24,2) := 0; temp_flue_gas_boiler_one numeric(24,2) := 0; cur_status_boiler_two numeric(24, 2) := 0 ; temp_out_boiler_two numeric(24,2) :=0; temp_in_boiler_two numeric(24,2) :=0; temp_water_boiler_two numeric(24,2) := 0; temp_flue_gas_boiler_two numeric(24,2) := 0; cur_status_pump_one numeric(24,2) := 0; frequency_pump_one numeric(24,2) := 0; cur_status_pump_two numeric(24,2) := 0; frequency_pump_two numeric(24,2) := 0; cur_status_pump_three numeric(24,2) := 0; frequency_pump_three numeric(24,2) := 0; is_exits INT := 0; register_address VARCHAR(50); value NUMERIC(24,2); mt_num varchar(20); -- 游标:简化为普通游标(无需 REF CURSOR) base_param CURSOR FOR SELECT cra.mt_num::VARCHAR, COALESCE(MAX(cra.cur_value), 0)::NUMERIC(24,2) FROM collection_params_manage cra WHERE cra.mt_num IS NOT NULL and cra.system_type = '3' and cra.device_ledger_id != '0243b3a898d85f3a1205a2d8cainuan01' and cra.device_ledger_id != '0243b3a898d85f3a1205a2d8cainuan100' and TO_CHAR(cra.cur_time, 'YYYY-MM-DD HH24') = cur_time_in GROUP BY cra.cur_time::DATE, cra.mt_num; BEGIN -- ------------------------------ -- 4. 遍历游标获取寄存器参数(严格关闭游标) -- ------------------------------ OPEN base_param; BEGIN -- 游标操作的异常处理块 LOOP FETCH NEXT FROM base_param INTO register_address, value; EXIT WHEN NOT FOUND; RAISE NOTICE 'Processing: % = %', register_address, value; -- 调试信息 -- 根据寄存器地址映射参数值 -- 根据寄存器地址映射参数值 CASE WHEN register_address IN ('PLC1500_DB611704', 'PLC1500_DB611694') THEN cur_status_boiler_one := CASE WHEN value > 0 THEN 1 ELSE 0 END; WHEN register_address = 'PLC1500_DB611686' THEN temp_out_boiler_one := value; WHEN register_address = 'PLC1500_DB611684' THEN temp_in_boiler_one := value; WHEN register_address = 'PLC1500_DB611688' THEN temp_water_boiler_one := value; WHEN register_address = 'PLC1500_DB611690' THEN temp_flue_gas_boiler_one := value; WHEN register_address IN ('PLC1500_DB611692', 'PLC1500_DB611706') THEN cur_status_boiler_two := CASE WHEN value > 0 THEN 1 ELSE 0 END; WHEN register_address = 'PLC1500_DB611698' THEN temp_out_boiler_two := value; WHEN register_address = 'PLC1500_DB611696' THEN temp_in_boiler_two := value; WHEN register_address = 'PLC1500_DB611700' THEN temp_water_boiler_two := value; WHEN register_address = 'PLC1500_DB611702' THEN temp_flue_gas_boiler_two := value; WHEN register_address = 'DBX83624' THEN cur_status_pump_one := value; WHEN register_address = 'DB612034' THEN frequency_pump_one := value; WHEN register_address = 'DBX83620' THEN cur_status_pump_two := value; WHEN register_address = 'DB612050' THEN frequency_pump_two := value; WHEN register_address = 'DBX83630' THEN cur_status_pump_three := value; WHEN register_address = 'DB612066' THEN frequency_pump_three := value; ELSE END CASE; END LOOP; EXCEPTION WHEN OTHERS THEN -- 游标异常时记录错误 RAISE NOTICE '游标遍历失败(设备:蒸汽机): %', SQLERRM; END; CLOSE base_param; -- 确保游标最终关闭 RAISE NOTICE '关闭游标'; -- ------------------------------ -- 5. 插入历史数据(处理唯一约束冲突) -- ------------------------------ SELECT COUNT(1) INTO is_exits FROM report_heating_run_param_his WHERE cur_time = cur_time_in; IF is_exits = 0 THEN INSERT INTO public.report_heating_run_param_his ( id, cur_date, cur_time, cur_status_boiler_one , temp_out_boiler_one , temp_in_boiler_one , temp_water_boiler_one , temp_flue_gas_boiler_one , cur_status_boiler_two , temp_out_boiler_two , temp_in_boiler_two , temp_water_boiler_two , temp_flue_gas_boiler_two , cur_status_pump_one , frequency_pump_one , cur_status_pump_two , frequency_pump_two , cur_status_pump_three , frequency_pump_three ) VALUES ( REPLACE(uuid_generate_v1mc()::TEXT, '-', ''), LEFT(cur_time_in, 10)::DATE, cur_time_in, cur_status_boiler_one , temp_out_boiler_one , temp_in_boiler_one , temp_water_boiler_one , temp_flue_gas_boiler_one , cur_status_boiler_two , temp_out_boiler_two , temp_in_boiler_two , temp_water_boiler_two , temp_flue_gas_boiler_two , cur_status_pump_one , frequency_pump_one , cur_status_pump_two , frequency_pump_two , cur_status_pump_three , frequency_pump_three ); END IF; EXCEPTION WHEN OTHERS THEN -- 主事务异常时,记录错误 RAISE NOTICE '存储过程执行失败(设备:采暖系统,时间:%): %', cur_time_in, SQLERRM; END; $procedure$ ;