############################## ##@author:gong.chengbo ## ##@createdate:2023-08-10 ## ##@for:用于归档工单状态清单 ## ############################## drop procedure if exists UpdateMostatus; create definer = admin@`%` procedure UpdateMostatus() BEGIN REPLACE into reportdata.Mostatus(area1,MESmoname,ERPmoname,eqpid,prodname,proddesc,crusize,stovetime,feeding_task_id,crucible,subprod,mostatus,mostatusdesc,finish_time,runtime) select left(ft.stove_no,1) area1,ft.order_no MESmoname,co.job_code ERPmoname,ft.stove_no eqpid,ft.product_no prodname,ft.product_name proddesc, co.thermal_field crusize,ft.update_time stovetime,ft.feeding_task_id,fd.factory crucible, case when LOCATE('自产',product_name) >0 then mid(product_name,LOCATE('自产',product_name)+3,6) when LOCATE('代工',product_name) >0 then mid(product_name,LOCATE('代工',product_name)+3,6) end subprod, co.finish_flag mostatus, case when co.finish_flag = '1' then '完结' when co.finish_flag = '0' then '非完结' end mostatusdesc, case when co.finish_flag = '1' then f.max_time end finish_time, case when co.finish_flag = '1' then datediff(f.max_time,ft.update_time) end rutime from mes_sync.mes_furnace_task ft LEFT JOIN mes_sync.mes_crystal_order co on(ft.order_no = co.order_no) LEFT JOIN mes_sync.mes_feeding_detail fd on(ft.feeding_task_id = fd.feeding_task_id and fd.material_type = '1') left join ( SELECT DISTINCT order_no,min(finish_rod) finish_rod FROM mes_sync.`mes_stick_task` GROUP BY order_no ) st on (ft.order_no = st.order_no) left join ( SELECT DISTINCT order_no,max(create_time) max_time from mes_sync.mes_production GROUP BY order_no ) f on(f.order_no = ft.order_no) where 1=1 and ft.`status` = '3' # 已正常投炉 and ft.type = '1' #初装 and fd.material_type = '1' #material_type为'1'的是坩埚 order by ft.create_time desc; ##该炉台有新工单的,即使上一棒未完结的,也更新成完结 update reportdata.mostatus mo,(SELECT eqpid,max(stovetime) newtime from reportdata.mostatus group by eqpid) st set mo.mostatusdesc = '完结' ,mo.mostatus = '1' where 1=1 and mo.eqpid = st.eqpid and mo.stovetime < st.newtime; ##异常完结的更新完结时间及运行时间 update reportdata.mostatus mo inner join (SELECT DISTINCT order_no, max(create_time) max_time, max(substring(code, 11, 1)) rx from mes_sync.mes_production GROUP BY order_no) f on (mo.MESmoname = f.order_no and mo.finish_time is null and mo.mostatus = '1') set mo.finish_time = f.max_time, mo.mostatus = '1', mo.mostatusdesc = '完结', mo.runtime = datediff(f.max_time, mo.stovetime); ##更新20天前未完结的 update reportdata.mostatus mo inner join (SELECT DISTINCT order_no, max(create_time) max_time, max(substring(code, 11, 1)) rx from mes_sync.mes_production GROUP BY order_no) f on (mo.MESmoname = f.order_no and mo.finish_time is null and mo.mostatus = '0' and mo.stovetime