From 3f2c3fc782b2f34863e809b24c342880640bfc14 Mon Sep 17 00:00:00 2001 From: xiaochou164 Date: Fri, 11 Aug 2023 16:59:57 +0800 Subject: [PATCH] =?UTF-8?q?=E5=A2=9E=E5=8A=A0=E5=BD=92=E6=A1=A3=E7=82=89?= =?UTF-8?q?=E5=8F=B0=E6=97=A5=E5=BF=97=E8=A1=A8?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- 报表sql/CrystalbarDullList.sql | 63 ++++++++++ 报表sql/EqpOnStoveStatus.sql | 118 ++++++++++++++++++ .../存储过程&定时任务/存储过程/CheckError.sql | 15 +++ .../存储过程&定时任务/存储过程/NoticeError.sql | 0 .../存储过程/UpdateEqpStatusLogs.sql | 99 +++++++++++++++ 5 files changed, 295 insertions(+) create mode 100644 报表sql/CrystalbarDullList.sql create mode 100644 报表sql/EqpOnStoveStatus.sql create mode 100644 数据库迁移sql/存储过程&定时任务/存储过程/CheckError.sql create mode 100644 数据库迁移sql/存储过程&定时任务/存储过程/NoticeError.sql create mode 100644 数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpStatusLogs.sql diff --git a/报表sql/CrystalbarDullList.sql b/报表sql/CrystalbarDullList.sql new file mode 100644 index 0000000..933acdb --- /dev/null +++ b/报表sql/CrystalbarDullList.sql @@ -0,0 +1,63 @@ +select row_number() over (), + mp.code, + mp.order_no, + mp.stove_no, + eq.area, + eq.area1, + mp.product_no, + mp.product_name, + mp.weight, + mp.length, + mp.update_time outtime, + TIMESTAMPDIFF(HOUR,mp.update_time,now()) +from mes_sync.mes_production mp +left join reportdata.equipment eq on (mp.stove_no = eq.eqpid) +where is_transport = 0 +and code not in +( +'YN342A002113N', +'YN341A086121N', +'YN341A086122N', +'YN341A086123N', +'YN341A086124N', +'YN341A086125W', +'YN341A009133W', +'YD352W679141W', +'YN351A074255W', +'YN351B125252N', +'YN351A004243N', +'YN351A031246N', +'YN351B120221W', +'YN351B125253W', +'YN351A004244N', +'YN351A094234W', +'YN351C208253N', +'YN351B135452N', +'YN351C191451W', +'YN351B113353W', +'YN361E317143W', +'YN361D245143WYL', +'YN362W674134N', +'YN362F450144N', +'YN362D274233N', +'YN372C200112N', +'YN372A040112N', +'YN362W679252W', +'YN362H566355N', +'YN371A048152N', +'YN372A042154N', +'YN371A044232N', +'YN372W685201W', +'YN372B155241W', +'YN372G537261N', +'YN372C236153N', +'YN372H633151N' +) +order by outtime; + + + + + + + diff --git a/报表sql/EqpOnStoveStatus.sql b/报表sql/EqpOnStoveStatus.sql new file mode 100644 index 0000000..58202a7 --- /dev/null +++ b/报表sql/EqpOnStoveStatus.sql @@ -0,0 +1,118 @@ +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; +#drop table eqponstovestatustmp + +###有工单、有投入、未产出 +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'); + + +select * +from eqponstovestatustmp; + + + + + diff --git a/数据库迁移sql/存储过程&定时任务/存储过程/CheckError.sql b/数据库迁移sql/存储过程&定时任务/存储过程/CheckError.sql new file mode 100644 index 0000000..ecf1948 --- /dev/null +++ b/数据库迁移sql/存储过程&定时任务/存储过程/CheckError.sql @@ -0,0 +1,15 @@ + + +select count(1) from siteonlinecrucibleyield +where 1=1 +and mfgdate > CONCAT(dATE_FORMAT(now() - 8.5 / 24,'%Y-%m-%d'),'01') +and adjustcrucible is null + + +select CONCAT(dATE_FORMAT(now() - 8.5 / 24,'%Y-%m-'),'01') + + +SELECT DATE_SUB(dATE_FORMAT(now() - 8.5 / 24,'%Y-%m-%d'), INTERVAL 1 DAY); + + + diff --git a/数据库迁移sql/存储过程&定时任务/存储过程/NoticeError.sql b/数据库迁移sql/存储过程&定时任务/存储过程/NoticeError.sql new file mode 100644 index 0000000..e69de29 diff --git a/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpStatusLogs.sql b/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpStatusLogs.sql new file mode 100644 index 0000000..e751d20 --- /dev/null +++ b/数据库迁移sql/存储过程&定时任务/存储过程/UpdateEqpStatusLogs.sql @@ -0,0 +1,99 @@ +drop procedure if exists UpdateEqpStatusLogs; +create + definer = admin@`%` procedure UpdateEqpStatusLogs(in begindate datetime, in enddate datetime) +BEGIN + ##1 报料,2 加料,3 开副室,4 晶棒产出,5 拆清 + if begindate = '2000-01-01 01:00:00' then + set begindate = dATE_FORMAT( + date_add(DATE_SUB(dATE_FORMAT(now() - 8.5 / 24, '%Y-%m-%d'), interval 1 day), interval 510 minute), + '%Y-%m-%d %k:%i:%s'); + end if; + + set @logmaxtdate = + (select dATE_FORMAT(date_add(dATE_FORMAT(max(eventtime) - 8.5 / 24, '%Y-%m-%d'), interval 510 minute), + '%Y-%m-%d %k:%i:%s') + from eqponstatuslogs); + + if @logmaxtdate < begindate then + set begindate = @logmaxtdate; + end if; + + if enddate = '2000-01-01 01:00:00' then + set enddate = dATE_FORMAT(date_add(dATE_FORMAT(now() - 8.5 / 24, '%Y-%m-%d'), interval 510 minute), + '%Y-%m-%d %k:%i:%s'); + end if; + +###报料记录 + insert into eqponstatuslogs(eqpname, event, eventtime, eventid, eqpid, eventtype) + select substring(crystal_code, 5, 5) eqpname, + case + when report_type = '1' then '初装报料' + when report_type = '2' then concat(substring(task_code, 13, 1), '次加料报料') + else '' end event, + update_time, + task_code, + eq.eqpid, + '1' + from mes_sync.mes_report_task mrt + left join reportdata.equipment eq on (substring(mrt.crystal_code, 5, 5) = eq.eqpname) + where update_time between begindate and enddate + order by create_time desc; + +###加料记录 + insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype) + SELECT substring(order_no, 5, 5) eqpname, + stove_no, + case + when feeding_task_code like '%CZ%' then '初装加料' + when feeding_task_code like '%JL%' then concat(substring(feeding_task_code, 13, 1), '加次第', + right(task_code, 1), '桶加料') end event, + ft.update_time, + feeding_task_code, + '2' + from mes_sync.mes_furnace_task ft + right join mes_sync.mes_feeding_detail fd + on (ft.feeding_task_id = fd.feeding_task_id and fd.material_type = '2') + where ft.`status` = '3' + and ft.update_time between begindate and enddate; + +###开副室记录 + insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype) + select substring(order_no, 5, 5) eqpname, + stove_no, + '开副室' event, + opening_time, + code, + '3' + from mes_sync.mes_sub_chamber_task + where opening_time between begindate and enddate; + +###晶棒产出 + insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype) + select substring(order_no, 5, 5) eqpname, + stove_no, + concat(right(code, 3), '晶棒产出'), + update_time, + code, + '4' + from mes_sync.mes_production + where update_time between begindate and enddate; + +###拆清 + insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype, eventstatus) + select substring(order_no, 5, 5) eqpname, + stove_no, + '拆清', + update_time, + order_no, + '5', + status + from mes_sync.mes_dismantle_task + where 1 = 1 + and update_time between begindate and enddate + and status = '3'; + + ##更新归档时间 + update eqponstatuslogs + set savedate = now() + where eventtime between begindate and enddate; +end