YZ_MES/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpOnStoveStatusLog.sql

169 lines
5.2 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

##############################
##@author:gong.chengbo ##
##@createdate:2023-08-10 ##
##@for: ##
##############################
drop procedure if exists UpdateEqpOnStoveStatusLog;
create
definer = admin@`%` procedure UpdateEqpOnStoveStatusLog() comment '更新开炉记录日志表'
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),
firststovetime datetime,
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 eql.eqpid, substring(eql.eventid, 1, 10) mesmoname, max(eql.eventtime)
from eqponstatuslogs eql
left join reportdata.mostatus mo on (eql.mesmoname = mo.MESmoname)
where mo.mostatus = '0'
group by eql.eqpid) b on (es.eqpid = b.eqpid)
set es.mesmoname = b.mesmoname;
##1 2 3 4 5
update eqponstovestatustmp eqs
left join
(select mesmoname, min(eventtime) stovetime
from eqponstatuslogs
where eventtype = '加料'
group by mesmoname) eql on eqs.mesmoname = eql.mesmoname
set eqs.firststovetime = eql.stovetime;
update eqponstovestatustmp eqs
left join
(select es.eqpid,
epl.mesmoname,
max(case when eventtype = '报料' then eventtime end) lastreporttime,
max(case when eventtype = '加料' then eventtime end) laststovetime,
max(case when eventtype = '开副室' then eventtime end) lastopentime,
max(case when eventtype = '晶棒产出' then eventtime end) lastouttime,
max(case when eventtype = '拆清' 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,
firststovetime,
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;