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

186 lines
7.0 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 ##
##############################
#
drop procedure if exists UpdateMesMoDailyYield;
CREATE DEFINER = CURRENT_USER PROCEDURE UpdateMesMoDailyYield()
BEGIN
###
DROP TABLE IF EXISTS mesmodailyyieldtemp;
CREATE TABLE mesmodailyyieldtemp
(
mesmoname varchar(255) not null comment 'MES工单/炉次号',
erpmoname varchar(255) null comment 'ERP工单号',
eqpid varchar(255) not null comment '炉台号',
area varchar(255) null comment '车间',
area1 varchar(255) null comment '片区',
mfgdate datetime null comment '归档时间-以完结出炉时间',
finishdate datetime null comment '完结时间',
moprod varchar(255) null comment '工单产品',
moprodname varchar(255) null comment '工单产品物料编码',
moproddesc varchar(255) null comment '工单物料描述',
stovetime datetime null comment '初投时间',
crusize varchar(255) null comment '热场尺寸',
crucible varchar(255) null comment '坩埚厂商',
cruciblesn varchar(255) null comment '坩埚编码',
adjustcruciblecode varchar(255) null comment '修正后的坩埚简称编码',
adjustcrucible varchar(255) null comment '修正后的坩埚简称',
totalstoveweight decimal(10, 3) null comment '投炉总重',
totaloutweight decimal(10, 3) null comment '出炉总重',
totallength int null comment '出炉长度',
totalqclength int null comment '出炉检验有效长度',
rod decimal(10, 3) null comment '圆棒折重系数',
totalqcweight decimal(10, 3) null comment '总出炉有效重量-圆棒',
totaldays decimal(10, 3) null comment '工单运行时长',
mostatus varchar(5) null comment 'MES中工单状态'
);
##MES工单的清单
replace into mesmodailyyieldtemp(mesmoname, eqpid, erpmoname, mostatus, moprodname, moproddesc)
select distinct order_no, stove_no, job_code, status, material_code, material_name
from mes_sync.mes_crystal_order
where 1 = 1
and status <> '2' ##
and status <> '0' ##
order by order_no;
###
update mesmodailyyieldtemp mmd
inner join reportdata.mostatus mo on mmd.mesmoname = mo.MESmoname
inner join reportdata.equipment eq on mmd.eqpid = eq.eqpid
set mmd.stovetime = mo.stovetime,
mmd.moprod = mo.subprod,
mmd.area = eq.area,
mmd.area1 = eq.area1,
mmd.finishdate = mo.finish_time
where 1=1;
###
update mesmodailyyieldtemp mmd
left join
(SELECT distinct ft.order_no mesmoname,
fd.factory crucible,
fd.serial_no cruciblesn,
replace(substring(material_name, 1, 3), '', '') crusize
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 = '1')) cru on (mmd.mesmoname = cru.mesmoname)
set mmd.cruciblesn = cru.cruciblesn,
mmd.crucible = cru.crucible,
mmd.crusize = cru.crusize
where 1=1;
###
update mesmodailyyieldtemp mmd
set mmd.totaldays = datediff(finishdate, stovetime)
where 1 = 1
and mmd.finishdate is not null
and mmd.stovetime is not null;
###
update mesmodailyyieldtemp mmd
set mmd.mfgdate = DATE_FORMAT(DATE_add(mmd.finishdate, interval -510 MINUTE), '%Y-%m-%d')
where mfgdate is null;
##
update mesmodailyyieldtemp mmd
INNER JOIN reportdata.adjustcruc ac on (mmd.mesmoname = ac.mesmoname)
set mmd.adjustcrucible = ac.crucible
where mmd.adjustcrucible is null;
##
update mesmodailyyieldtemp mmd
INNER JOIN reportdata.dict d on (mmd.adjustcrucible = d.dictkey and d.cate = 'cruccode')
set mmd.adjustcruciblecode = d.value
where 1=1;
update mesmodailyyieldtemp mmd
INNER JOIN reportdata.dict d on (mmd.crucible = d.dictkey and d.cate = 'crucname')
set mmd.adjustcruciblecode = d.value,
mmd.adjustcrucible = d.value1
where 1=1;
####
update mesmodailyyieldtemp mmd
set adjustcrucible = '佑鑫',
adjustcruciblecode = 'YX'
where 1 = 1
and cruciblesn like 'D%'
and adjustcruciblecode is null;
####
update mesmodailyyieldtemp mmd
set adjustcrucible = '硕日',
adjustcruciblecode = 'SR'
where 1 = 1
and cruciblesn like 'SR%'
and adjustcruciblecode is null;
update mesmodailyyieldtemp mmd
left join
(SELECT ft.order_no mesmoname,
sum(fd.weight) stoveweight
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')
group by ft.order_no) d on (mmd.mesmoname = d.mesmoname)
set mmd.totalstoveweight = d.stoveweight
where 1=1;
update mesmodailyyieldtemp mmd
left join
(select order_no mesmoname, sum(weight) outweight, sum(length) 'length'
from mes_sync.mes_production
group by order_no) t on (mmd.mesmoname = t.mesmoname)
set mmd.totallength = t.length,
mmd.totaloutweight = t.outweight
where 1=1;
###
update mesmodailyyieldtemp mmd
INNER JOIN (select substring(production_code, 1, 10) mesmoname, sum(draw_length) qclength
FROM mes_sync.mes_round_bar
where right(code, 1) = '0'
group by substring(production_code, 1, 10)) ps on (mmd.mesmoname = ps.mesmoname)
set mmd.totalqclength = ps.qclength
where mmd.totalqclength is null;
###
update mesmodailyyieldtemp mmd
INNER JOIN mes_sync.yz_mes_spec yms on (mmd.moprod = yms.spec_code)
set mmd.rod = yms.hair_rod_coefficient
where mmd.rod is null;
###MES中未维护的使用自己维护的补充
update mesmodailyyieldtemp mmd
INNER JOIN reportdata.prod p on (mmd.moprod = p.code)
set mmd.rod = p.round
where mmd.rod is null;
###WFSY技术实验规格
update mesmodailyyieldtemp mmd
INNER JOIN
(
select distinct substring(moprodname, 1, 5) subprod, rod
from mesmodailyyieldtemp
where rod is not null
) p on (substring(mmd.moprodname,1,5) = p.subprod)
set mmd.rod = p.rod
where mmd.moprod = 'WFSY' and mmd.rod is null;
###
update mesmodailyyieldtemp mmd
set mmd.totalqcweight = mmd.totalqclength / mmd.rod
where totalqcweight is null;
##
replace into reportdata.mesmodailyyield
select *
from mesmodailyyieldtemp
order by mfgdate desc;
DROP TABLE mesmodailyyieldtemp;
END;