diff --git a/报表sql/EqpOnStoveStatus.sql b/报表sql/EqpOnStoveStatus.sql index 58202a7..e063bd2 100644 --- a/报表sql/EqpOnStoveStatus.sql +++ b/报表sql/EqpOnStoveStatus.sql @@ -49,8 +49,6 @@ set eqs.lastreporttime = b.lastreporttime, eqs.lastouttime = b.lastouttime, eqs.lastchaiqingtime = b.lastchaiqingtime, eqs.finishtime = b.finishtime; -#drop table eqponstovestatustmp - ###有工单、有投入、未产出 update eqponstovestatustmp set eqpstatus = '投料后未产出' @@ -109,10 +107,29 @@ where 1 = 1 and lastouttime <= date_format(date_sub(now(), interval 5 day), '%Y-%m-%d'); +###运行异常 +update eqponstovestatustmp +set eqpstatus = '拉棒时间超3天' +where 1 = 1 + and laststovetime is not null + and laststovetime <= date_format(date_sub(now(), interval 3 day), '%Y-%m-%d'); + +update eqponstovestatustmp esp +inner join mes_sync.mes_crystal_order mco on (esp.mesmoname = mco.order_no) +inner join reportdata.mostatus mo on (esp.mesmoname = mo.MESmoname) +set esp.crusize = mco.thermal_field,esp.subprod = mo.subprod; + +insert into eqponstovestatus select * from eqponstovestatustmp; +update eqponstovestatus set savedate = now() where savedate is null; +update eqponstovestatus set mfgdate = date_format(now()-8.5/24,'%Y-%m-%d') where mfgdate is null; +#drop table eqponstovestatustmp + + + diff --git a/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpOnStoveStatusLog.sql b/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpOnStoveStatusLog.sql new file mode 100644 index 0000000..c124654 --- /dev/null +++ b/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpOnStoveStatusLog.sql @@ -0,0 +1,150 @@ +drop procedure if exists UpdateEqpOnStoveStatusLog; +create + definer = admin@`%` procedure UpdateEqpOnStoveStatusLog() +BEGIN +DROP TABLE IF EXISTS `eqponstovestatustmp`; +create table eqponstovestatustmp +( + area varchar(50), + area1 varchar(50), + eqpid varchar(50), + mesmoname varchar(50), + eqpmodel varchar(50), + eqpstatus varchar(50), + crusize varchar(50), + subprod varchar(50), + lastreporttime datetime, + laststovetime datetime, + lastopentime datetime, + lastouttime datetime, + finishtime datetime, + lastchaiqingtime datetime +); +replace into eqponstovestatustmp(area, area1, eqpid, eqpmodel) +select area, area1, eqpid, eqpmodel +from reportdata.equipment; + +###更新最新有执行记录的工单 +update eqponstovestatustmp es + left join + (select eqpid, substring(eventid, 1, 10) mesmoname, max(eventtime) + from eqponstatuslogs + group by eqpid) b on (es.eqpid = b.eqpid) +set es.mesmoname = b.mesmoname; + +##1 报料,2 加料,3 开副室,4 晶棒产出,5 拆清 + +update eqponstovestatustmp eqs + left join + (select es.eqpid, + epl.mesmoname, + max(case when eventtype = '1' then eventtime end) lastreporttime, + max(case when eventtype = '2' then eventtime end) laststovetime, + max(case when eventtype = '3' then eventtime end) lastopentime, + max(case when eventtype = '3' then eventtime end) lastouttime, + max(case when eventtype = '3' then eventtime end) lastchaiqingtime, + case when substring(eventid,13,1) = 'W' then eventtime end finishtime + from eqponstatuslogs es + inner join eqponstovestatustmp epl on (substring(es.eventid, 1, 10) = epl.mesmoname) + group by es.eqpid) b on (eqs.eqpid = b.eqpid) +set eqs.lastreporttime = b.lastreporttime, + eqs.laststovetime = b.laststovetime, + eqs.lastopentime = b.lastopentime, + eqs.lastouttime = b.lastouttime, + eqs.lastchaiqingtime = b.lastchaiqingtime, + eqs.finishtime = b.finishtime; +###有工单、有投入、未产出 +update eqponstovestatustmp +set eqpstatus = '投料后未产出' +where 1 = 1 + and laststovetime is not null + and lastouttime is null + and mesmoname is not null + and laststovetime >= date_format(date_sub(now(), interval 20 day), '%Y-%m-%d'); + +###无工单、无投入、无产出、无报料 +update eqponstovestatustmp +set eqpstatus = '完结后未报料' +where 1 = 1 + and laststovetime is null + and lastouttime is null + and mesmoname is null; + +###循环段产出中 +update eqponstovestatustmp +set eqpstatus = '循环段产出中' +where 1 = 1 + and laststovetime is not null + and lastouttime is not null + and mesmoname is not null + and lastouttime >= date_format(date_sub(now(), interval 4 day), '%Y-%m-%d'); + +###工单异常 +update eqponstovestatustmp +set eqpstatus = '工单异常' +where 1 = 1 + and lastouttime <= date_format(date_sub(now(), interval 25 day), '%Y-%m-%d'); + +###工单异常 +update eqponstovestatustmp +set eqpstatus = '报料未投炉' +where 1 = 1 + and lastreporttime is not null + and mesmoname is not null + and lastouttime is null + and laststovetime is null; + +###报料异常 +update eqponstovestatustmp +set eqpstatus = '报料异常' +where 1 = 1 + and lastreporttime is not null + and laststovetime is null + and lastreporttime <= date_format(date_sub(now(), interval 3 day), '%Y-%m-%d'); + +###拆清异常 +update eqponstovestatustmp +set eqpstatus = '拆清异常' +where 1 = 1 + and lastouttime is not null + and lastchaiqingtime is null + and lastouttime <= date_format(date_sub(now(), interval 5 day), '%Y-%m-%d'); + + +###运行异常 +update eqponstovestatustmp +set eqpstatus = '拉棒时间超3天' +where 1 = 1 + and laststovetime is not null + and laststovetime <= date_format(date_sub(now(), interval 3 day), '%Y-%m-%d'); + +update eqponstovestatustmp esp +inner join mes_sync.mes_crystal_order mco on (esp.mesmoname = mco.order_no) +inner join reportdata.mostatus mo on (esp.mesmoname = mo.MESmoname) +set esp.crusize = mco.thermal_field,esp.subprod = mo.subprod; + +insert into eqponstovestatus( + area, + area1, + eqpid, + mesmoname, + eqpmodel, + eqpstatus, + crusize, + subprod, + lastreporttime, + laststovetime, + lastopentime, + lastouttime, + finishtime, + lastchaiqingtime +) +select * +from eqponstovestatustmp; + + +update eqponstovestatus set savedate = now() where savedate is null; +update eqponstovestatus set mfgdate = date_format(now()-8.5/24,'%Y-%m-%d') where mfgdate is null; +drop table eqponstovestatustmp; +END; + diff --git a/数据库迁移sql/存储过程&定时任务/定时任务/UpdateEqpOnStoveStatusLog.sql b/数据库迁移sql/存储过程&定时任务/定时任务/UpdateEqpOnStoveStatusLog.sql new file mode 100644 index 0000000..de08ba0 --- /dev/null +++ b/数据库迁移sql/存储过程&定时任务/定时任务/UpdateEqpOnStoveStatusLog.sql @@ -0,0 +1,7 @@ +create definer = admin@`%` event UpdateEqpOnStoveStatusLog on schedule + every '1' DAY + starts '2023-08-10 08:45:00' + enable + comment '每天归档炉台日志' + do + call UpdateEqpOnStoveStatusLog();