YZ_MES/数据库迁移sql/存储过程/UpdateEqpStatusLogs.sql

144 lines
5.7 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 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, rx, eventstatus,mesmoname)
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,
'报料',
case
when report_type = '1' then '0'
when report_type = '2' then substring(task_code, 13, 1)
else '' end rx,
'已完成', # 1:2: 3: 4:
substring(task_code, 1, 10)
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, rx, eventstatus, mesmoname)
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,
'加料',
case
when feeding_task_code like '%CZ%' then '0'
else substring(feeding_task_code, 13, 1) end rx,
case
when ft.status = 1 then '待处理'
when ft.status = 2 then '进行中'
when ft.status = 3 then '已完成'
when ft.status = 4 then '暂停' end, # 1:2: 3: 4:
substring(feeding_task_code, 1, 10)
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 1 = 1
and ft.update_time between begindate and enddate;
###
insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype, rx, eventstatus, mesmoname)
select substring(order_no, 5, 5) eqpname,
stove_no,
concat(
case
when type = 0 then ''
when type = 1 then '正常取棒'
when type = 2 then '断棒'
when type = 3 then '余料提出' end,
'/开副室/', case when cold_stoking = 0 then '焖炉' else '' end) event,# 1: 2: 3:
opening_time,
code,
'开副室',
substring(code, 11, 1),
'已完成',
substring(code, 1, 10)
from mes_sync.mes_sub_chamber_task
where 1 = 1
and delete_flag = '0'
and opening_time between begindate and enddate;
###
insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype, rx, eventstatus, mesmoname)
select substring(order_no, 5, 5) eqpname,
stove_no,
concat(right(code, 3), '晶棒产出'),
update_time,
code,
'产出晶棒',
substring(code, 11, 1),
case
when is_transport = 0 then '未质检'
when is_transport = 1 then '已质检' end,
substring(code, 1, 10)
from mes_sync.mes_production
where update_time between begindate and enddate;
###
insert into eqponstatuslogs(eqpname, eqpid, event, eventtime, eventid, eventtype, rx, eventstatus, mesmoname)
select substring(order_no, 5, 5) eqpname,
stove_no,
'拆清',
update_time,
order_no,
'拆清',
'99',
case
when status = 1 then '待处理'
when status = 2 then '进行中'
when status = 3 then '已完成' end,
order_no
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