You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

645 lines
34 KiB
XML

<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="com.foreverwin.mesnac.common.mapper.BoardMapper">
<!--设备运行状态-->
<select id="resourceRunData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT
MAX(CASE WHEN STATUS = 'RUN' THEN QTY ELSE 0 END)RUN,
MAX(CASE WHEN STATUS = 'DOW' THEN QTY ELSE 0 END)"STOP",
MAX(CASE WHEN STATUS = 'WARN' THEN QTY ELSE 0 END)IDLE,
MAX(CASE WHEN STATUS = 'FREE' THEN QTY ELSE 0 END)IDLEA
FROM
( SELECT "STATUS", COUNT(1)QTY FROM Z_RESOURCE_STATUS_RECEIVE GROUP BY "STATUS" )
</select>
<!--设备运行状态参数-->
<select id="resourceRunParamData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
WITH TPARAM AS(
SELECT
ZRSR.RESRCE,
R.DESCRIPTION RESOURCE_DESCRIPTION,
CF.VALUE,
CF.VALUE || '/' || R.DESCRIPTION NAME,
CASE
WHEN ZRSR.STATUS = 'RUN' THEN '#7FB80E' --'#1afa29'
WHEN ZRSR.STATUS = 'DOW' THEN '#F5A15B' --'#EF4136'
ELSE '#dbdbdb'
END STATUS_COLOR,
CASE
WHEN ZRSR.STATUS = 'RUN' THEN '运行'
WHEN ZRSR.STATUS = 'DOW' THEN '停机'
ELSE '空闲'
END STATUS_NAME,
ZEDR.S1 FEED_RATE,
ZEDR.S2 FEED_VALUE,
ZEDR.S3 SPINDLE_LOAD,
ZEDR.S4 SPINDLE_SPEED
FROM
Z_RESOURCE_STATUS_RECEIVE ZRSR
LEFT JOIN RESRCE R ON
R.RESRCE = ZRSR.RESRCE
AND R.SITE = '1000'
LEFT JOIN Z_EDC_DATA_RESOURCE ZEDR ON
ZEDR.RESRCE = ZRSR.RESRCE
LEFT JOIN CUSTOM_FIELDS cf ON
CF.HANDLE = R.HANDLE
AND CF."ATTRIBUTE" = 'RESOURCE_LOCATION'
),
TEMP AS(
SELECT
ZSD.RESRCE,
ZSD.DISPATCH_STATUS,
i.ITEM,
it.DESCRIPTION,
ZSD.ACTUAL_START_DATE,
ZSD.PROD_HOURS,
ZSD.DISPATCH_QTY,
ZSD.STEP_ID,
ZSD.ACTUAL_PROD_HOURS
FROM
Z_SFC_DISPATCH zsd
INNER JOIN Z_RESOURCE_STATUS_RECEIVE ZRSR ON
ZRSR.RESRCE = ZSD.RESRCE
INNER JOIN SHOP_ORDER SO ON
SO.SHOP_ORDER = ZSD.SHOP_ORDER
INNER JOIN ITEM i ON
I.HANDLE = SO.ITEM_BO
INNER JOIN ITEM_T IT ON
IT.ITEM_BO = I.HANDLE
AND IT.LOCALE = 'zh'
WHERE
ZSD.SITE = '1000'
AND ZSD.DISPATCH_STATUS IN(
'COMPLETE',
'START'
)
),
MN AS(
SELECT
*
FROM
(
SELECT
ROW_NUMBER() OVER(
PARTITION BY RESRCE
ORDER BY
DISPATCH_STATUS DESC,
ACTUAL_START_DATE DESC,
STEP_ID DESC
) rn,
RESRCE,
DISPATCH_STATUS,
ITEM,
DESCRIPTION,
DISPATCH_QTY,
PROD_HOURS,
ACTUAL_START_DATE,
STEP_ID,
ACTUAL_PROD_HOURS,
CASE
WHEN DISPATCH_STATUS = 'START' THEN(
SYSDATE -(
ACTUAL_START_DATE + 8 / 24
)
)* 24
ELSE NVL( 10000, ACTUAL_PROD_HOURS )
END WORK_HOUR
FROM
TEMP
)
WHERE
rn = 1
) SELECT
A.*,
B.ITEM,
B.DESCRIPTION ITEM_DESCRIPTION,
B.DISPATCH_QTY,
CASE
WHEN B.PROD_HOURS > B.WORK_HOUR THEN ROUND( WORK_HOUR / PROD_HOURS, 2 )
ELSE(
CASE
WHEN B.DISPATCH_STATUS = 'START' THEN 90
ELSE 100
END
)
END PROGRESS
FROM
TPARAM A
LEFT JOIN MN B ON
B.RESRCE = A.RESRCE
ORDER BY
A.VALUE,
B.ITEM
</select>
<select id="resourceFaultDescription" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT ROWNUM , T.* FROM (SELECT DISTINCT ZRFR.RESRCE, R.DESCRIPTION, ZRFR.DESCRIPTION FAULT_DESCRIPTION
FROM Z_RESOURCE_FAULT_RECEIVE ZRFR
INNER JOIN RESRCE R ON R.RESRCE = ZRFR.RESRCE AND R.SITE = #{site}
WHERE ZRFR.DESCRIPTION IS NOT NULL AND TO_CHAR(ZRFR.CREATED_DATE_TIME , 'YYYY-MM-DD') = TO_CHAR(SYSDATE ,'YYYY-MM-DD') ) T
WHERE ROWNUM &lt; 20
</select>
<!--月计划完成数-->
<select id="monthPlanCompleteData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT SUM(ZSD.DISPATCH_QTY) "value" FROM Z_SFC_DISPATCH zsd
WHERE ZSD.DISPATCH_STATUS != 'NEW' AND ZSD.SITE = #{site}
AND TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
</select>
<!--月完成数-->
<select id="monthCompleteData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT NVL(SUM(ZSD.DISPATCH_QTY),0) "value" FROM Z_SFC_DISPATCH zsd
WHERE ZSD.SITE = #{site} AND ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL')
AND TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.SHOP_ORDER IN (
SELECT SHOP_ORDER FROM Z_SFC_DISPATCH SO WHERE TO_CHAR(SO.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND TO_CHAR(SO.PLANNED_START_DATE+ 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
)
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
</select>
<!--月计划完成数和月完成数-->
<select id="monthCompleteAndPlanCompleteData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT A.CNT QTY_PLAN , B.CNT QTY_DONE , A.CNT - B.CNT QTY_HAND FROM
(SELECT SUM(ZSD.DISPATCH_QTY) CNT FROM Z_SFC_DISPATCH zsd
WHERE ZSD.DISPATCH_STATUS != 'NEW' AND ZSD.SITE = #{site}
AND TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
) A,
( SELECT NVL(SUM(ZSD.DISPATCH_QTY),0) CNT FROM Z_SFC_DISPATCH zsd
WHERE ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL')
AND TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.SHOP_ORDER IN (
SELECT SHOP_ORDER FROM Z_SFC_DISPATCH SO WHERE TO_CHAR(SO.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND TO_CHAR(SO.PLANNED_START_DATE+ 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
)
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
) B
</select>
<!--合格率-->
<select id="percentOfPass" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT 10 "min", 100 "max",
CASE WHEN SUM(QTY) = 0 THEN 0
ELSE NVL(ROUND(SUM(CASE WHEN RESULT = 'OK' THEN QTY ELSE 0 END)/SUM(QTY)*100,2),0) END "value", '%' "unit"
FROM (
SELECT ZT.SITE, ZT.SFC, ZT.RESULT, SC.QTY, RANK() OVER(PARTITION BY ZT.SITE, ZT.SFC ORDER BY ZT.CREATED_DATE_TIME DESC) AS ROW_ID
FROM Z_INSPECTION_TASK ZT
INNER JOIN SFC SC ON ZT.SITE = SC.SITE AND ZT.SFC = SC.SFC
WHERE ZT.SITE = #{site} AND ZT.CATEGORY = 'P' AND STATUS = 'COMPLETE'
AND TO_CHAR(ZT.CREATED_DATE_TIME + 8/24,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZT.WORK_CENTER = #{workCenter}
</if>
) WHERE ROW_ID = 1
GROUP BY SITE
</select>
<!--车间设备近三天运行数-->
<select id="resourceRunDataThreeDay" resultType="java.util.HashMap" parameterType="java.util.HashMap">
WITH TEMP AS (
SELECT DISTINCT ZSD.RESRCE , TO_CHAR(ZSD.ACTUAL_START_DATE,'MM-DD') DATE_TIME FROM Z_SFC_DISPATCH ZSD
WHERE ZSD.SITE = #{site} AND ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL','START')
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
AND ZSD.ACTUAL_START_DATE > (SELECT TO_DATE( TO_CHAR(SYSDATE-3 ,'YYYY-MM-DD') || ' 16:00:00' , 'YYYY-MM-DD HH24:MI:SS' ) DATE_TIME FROM DUAL )
)
SELECT A.DATE_TIME A_DATE , A.CNT A_CNT ,B.DATE_TIME B_DATE , B.CNT B_CNT ,C.DATE_TIME C_DATE , C.CNT C_CNT
FROM
(SELECT COUNT(RESRCE) CNT , TO_CHAR(SYSDATE-2 ,'MM-DD') DATE_TIME FROM TEMP WHERE DATE_TIME = TO_CHAR(SYSDATE-2 ,'MM-DD') ) A,
(SELECT COUNT(RESRCE) CNT , TO_CHAR(SYSDATE-1 ,'MM-DD') DATE_TIME FROM TEMP WHERE DATE_TIME = TO_CHAR(SYSDATE-1 ,'MM-DD') ) B,
(SELECT COUNT(RESRCE) CNT , TO_CHAR(SYSDATE ,'MM-DD') DATE_TIME FROM TEMP WHERE DATE_TIME = TO_CHAR(SYSDATE ,'MM-DD') ) C
</select>
<!--一次交检合格率-->
<select id="onceEspecially" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT L.MONTHS, L.XS_MONTHS, NVL(P.JJ_QTY,0) JJ_QTY, NVL(P.OK_QTY,0) OK_QTY, ROUND(NVL(P.OK_QTY,0)/NVL(P.JJ_QTY,1)*100,2) OK_RATE
FROM (
SELECT TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-4),'YYYYMM') MONTHS, TO_NUMBER(TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-4),'MM')) XS_MONTHS FROM DUAL
UNION
SELECT TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-3),'YYYYMM') MONTHS, TO_NUMBER(TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-3),'MM')) XS_MONTHS FROM DUAL
UNION
SELECT TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-2),'YYYYMM') MONTHS, TO_NUMBER(TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-2),'MM')) XS_MONTHS FROM DUAL
UNION
SELECT TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-1),'YYYYMM') MONTHS, TO_NUMBER(TO_CHAR(ADD_MONTHS(TRUNC(SYSDATE),-1),'MM')) XS_MONTHS FROM DUAL
UNION
SELECT TO_CHAR(SYSDATE, 'YYYYMM') MONTHS, TO_NUMBER(TO_CHAR(SYSDATE,'MM')) XS_MONTHS FROM DUAL
) L
LEFT JOIN (
SELECT TASK_MONTH, SUM(QTY) JJ_QTY, SUM(CASE WHEN RESULT = 'OK' THEN QTY ELSE 0 END) OK_QTY
FROM (
SELECT TO_CHAR(ZT.CREATED_DATE_TIME + 8/24, 'YYYYMM') TASK_MONTH, ZT.SFC, ZT.RESULT, SC.QTY,
ROW_NUMBER() OVER(PARTITION BY TO_CHAR(ZT.CREATED_DATE_TIME + 8/24, 'YYYYMM'),ZT.SFC, SC.QTY ORDER BY ZT.CREATED_DATE_TIME DESC) SEQ
FROM Z_INSPECTION_TASK ZT
INNER JOIN SFC SC ON ZT.SITE = SC.SITE AND SC.SFC = ZT.SFC
WHERE ZT.SITE = #{site} AND ZT.CATEGORY = 'P' AND ZT.STATUS = 'COMPLETE'
<if test="workCenter != null and workCenter != ''">
AND ZT.WORK_CENTER = #{workCenter}
</if>
) WHERE SEQ = 1
GROUP BY TASK_MONTH
) P ON L.MONTHS = P.TASK_MONTH
ORDER BY L.MONTHS
</select>
<!--完工进度-->
<select id="scheduleOfCompletion" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT
T.ITEM_NUMBER,
T.ITEM_DESC,
T.SHOP_ORDER,
T.PLANNED_COMP_DATE,
T.PLANNED_START_DATE,
CASE
WHEN SUM( T.CNT_HOURS )= 0 THEN '0%'
ELSE ROUND( SUM( T.CNT_HOURS )/ SUM( T.PROD_HOURS ), 2 )* 100 || '%'
END COMP_RATE
FROM
(
SELECT
CF.VALUE ITEM_NUMBER,
IT.DESCRIPTION ITEM_DESC,
SO.SHOP_ORDER,
SO.PLANNED_COMP_DATE,
SO.PLANNED_START_DATE,
ZSD.SFC,
ZSD.PROD_HOURS,
CASE
WHEN ZSD.ACTUAL_COMPLETE_DATE IS NOT NULL THEN ZSD.PROD_HOURS
WHEN ZSD.ACTUAL_COMPLETE_DATE IS NULL
AND ZSD.ACTUAL_START_DATE IS NOT NULL THEN 0
WHEN ZSD.ACTUAL_START_DATE IS NULL THEN 0
END CNT_HOURS
FROM
Z_SFC_DISPATCH ZSD
INNER JOIN SHOP_ORDER SO ON
SO.SHOP_ORDER = ZSD.SHOP_ORDER
INNER JOIN SFC S ON
S.SHOP_ORDER_BO = SO.HANDLE
INNER JOIN ITEM IM ON
IM.HANDLE = SO.ITEM_BO
LEFT JOIN ITEM_T IT ON
IT.ITEM_BO = IM.HANDLE
AND IT.LOCALE = 'zh'
LEFT JOIN CUSTOM_FIELDS CF ON
SO.HANDLE = CF.HANDLE
AND CF.ATTRIBUTE = 'ITEM_NUMBER'
LEFT JOIN CUSTOM_FIELDS CF1 ON
SO.HANDLE = CF1.HANDLE
AND CF1.ATTRIBUTE = 'FACTORY'
WHERE
ZSD.SITE = '1000'
AND CF1.VALUE = '6106'
<if test="workCenter != null and workCenter != ''">
AND ZSD.WORK_CENTER = #{workCenter}
</if>
AND ZSD.DISPATCH_STATUS != 'CANCEL'
AND TO_CHAR( SO.PLANNED_COMP_DATE + 8 / 24, 'YYYY-MM' )= TO_CHAR( SYSDATE, 'YYYY-MM' )
ORDER BY
ZSD.SHOP_ORDER,
ZSD.SFC
) T
GROUP BY
T.ITEM_NUMBER,
T.ITEM_DESC,
T.SHOP_ORDER,
T.PLANNED_COMP_DATE,
T.PLANNED_START_DATE
ORDER BY
T.PLANNED_START_DATE DESC
</select>
<!--异常待解决\异常已解决\异常正在处理-->
<select id="abnormalResolveData" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT COUNT(1) "value" FROM Z_ABNORMAL_BILL ZB
WHERE SITE = #{site} AND TO_CHAR(ZB.CREATED_DATE_TIME + 8/24,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZB.WORK_CENTER = #{workCenter}
</if>
<if test="status != null and status != ''">
<choose>
<when test="status.contains('unResolve')">
AND ZB.STATUS = 'N'
</when>
<when test="status.contains('resolve')">
AND ZB.STATUS = 'G'
</when>
<when test="status.contains('dealing')">
AND ZB.STATUS NOT IN ('N', 'G', 'Q')
</when>
</choose>
</if>
</select>
<!--异常响应情况-->
<select id="abnormalContent" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT CONTENT
FROM (
SELECT ZM.CONTENT FROM Z_ABNORMAL_BILL ZB
INNER JOIN Z_MESSAGE ZM ON ZB.HANDLE = ZM.OBJECT_BO
WHERE ZB.SITE = '1000' AND ZB.STATUS = 'N'
AND TO_CHAR(ZB.CREATED_DATE_TIME + 8/24, 'YYYY-MM') = TO_CHAR(SYSDATE, 'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZB.WORK_CENTER = #{workCenter}
</if>
ORDER BY ZB.CREATED_DATE_TIME DESC
) WHERE ROWNUM &lt;= 30
</select>
<!--焊接车间计划数-->
<select id="planDataFSW" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT SUM(ZSD.DISPATCH_QTY) "value" FROM Z_SFC_DISPATCH zsd
INNER JOIN OPERATION O ON O.OPERATION = ZSD.OPERATION
INNER JOIN OPERATION_T ot ON OT.OPERATION_BO = O.HANDLE AND OT.LOCALE = 'zh'
WHERE TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.WORK_CENTER = 'HJ' AND ZSD.SITE = #{site}
<choose>
<when test="operationDescription != null and operationDescription != ''">
AND OT.DESCRIPTION != ('焊接' )
</when>
<otherwise>
AND OT.DESCRIPTION = ('焊接' )
</otherwise>
</choose>
</select>
<!--焊接车间完成数-->
<select id="completeDataFSW" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT SUM(ZSD.DISPATCH_QTY) "value" FROM Z_SFC_DISPATCH zsd
INNER JOIN OPERATION O ON O.OPERATION = ZSD.OPERATION
INNER JOIN OPERATION_T ot ON OT.OPERATION_BO = O.HANDLE AND OT.LOCALE = 'zh'
WHERE TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL')
AND ZSD.WORK_CENTER = 'HJ' AND ZSD.SITE = #{site}
<choose>
<when test="operationDescription != null and operationDescription != ''">
AND OT.DESCRIPTION != ('焊接' )
</when>
<otherwise>
AND OT.DESCRIPTION = ('焊接' )
</otherwise>
</choose>
AND ZSD.SHOP_ORDER IN (
SELECT SHOP_ORDER FROM Z_SFC_DISPATCH SO WHERE TO_CHAR(SO.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND TO_CHAR(SO.PLANNED_START_DATE+ 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
)
</select>
<!--焊接车间计划数、完成数-->
<select id="planAndCompleteDataFSW" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT A.CNT QTY_PLAN , B.CNT QTY_DONE , A.CNT - B.CNT QTY_HAND FROM
(
SELECT SUM(ZSD.DISPATCH_QTY) CNT FROM Z_SFC_DISPATCH zsd
INNER JOIN OPERATION O ON O.OPERATION = ZSD.OPERATION
INNER JOIN OPERATION_T ot ON OT.OPERATION_BO = O.HANDLE AND OT.LOCALE = 'zh'
WHERE TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.WORK_CENTER = 'HJ' AND ZSD.SITE = #{site}
<choose>
<when test="operationDescription != null and operationDescription != ''">
AND OT.DESCRIPTION != ('焊接' )
</when>
<otherwise>
AND OT.DESCRIPTION = ('焊接' )
</otherwise>
</choose> ) A ,
(
SELECT SUM(ZSD.DISPATCH_QTY) CNT FROM Z_SFC_DISPATCH zsd
INNER JOIN OPERATION O ON O.OPERATION = ZSD.OPERATION
INNER JOIN OPERATION_T ot ON OT.OPERATION_BO = O.HANDLE AND OT.LOCALE = 'zh'
WHERE TO_CHAR(ZSD.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL')
AND ZSD.WORK_CENTER = 'HJ' AND ZSD.SITE = #{site}
<choose>
<when test="operationDescription != null and operationDescription != ''">
AND OT.DESCRIPTION != ('焊接' )
</when>
<otherwise>
AND OT.DESCRIPTION = ('焊接' )
</otherwise>
</choose>
AND ZSD.SHOP_ORDER IN (
SELECT SHOP_ORDER FROM Z_SFC_DISPATCH SO WHERE TO_CHAR(SO.PLANNED_COMP_DATE + 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
AND TO_CHAR(SO.PLANNED_START_DATE+ 8/24 , 'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
) ) B
</select>
<!--综合看板-->
<!--设备不同状态数-->
<select id="resourceStatusQty" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT SUM(CASE WHEN "TYPE" = 'Z' THEN 1 ELSE 0 END) Z_QTY,
SUM(CASE WHEN "TYPE" = 'S' THEN 1 ELSE 0 END) S_QTY,
SUM(CASE WHEN "TYPE" = 'Q' THEN 1 ELSE 0 END) Q_QTY
FROM Z_ABNORMAL_BILL ZB
WHERE SITE = '1000' AND TO_CHAR(ZB.CREATED_DATE_TIME,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
GROUP BY TO_CHAR(ZB.CREATED_DATE_TIME,'YYYY-MM')
</select>
<!--设备各异常处理状态-->
<select id="resourceAbnormalInfo" resultType="java.util.HashMap" parameterType="java.util.HashMap" >
SELECT TEMP.* , T.CNT FROM
(
SELECT '其他' TYPE_DESCRIPTION ,'Q' TYPE , 'N' STATUS , '待解决' STATUS_DESCRIPTION FROM DUAL
UNION
SELECT '其他' TYPE_DESCRIPTION ,'Q' TYPE , 'X' , '正在处理' FROM DUAL
UNION
SELECT '其他' TYPE_DESCRIPTION ,'Q' TYPE , 'SUCCESS' , '已解决' STATUS FROM DUAL
UNION
SELECT '质量', 'Z', 'N', '待解决' FROM DUAL
UNION
SELECT '质量', 'Z', 'X', '正在处理' FROM DUAL
UNION
SELECT '质量', 'Z', 'SUCCESS', '已解决' FROM DUAL
UNION
SELECT '设备', 'S', 'N' , '待解决' FROM DUAL
UNION
SELECT '设备', 'S', 'X' , '正在处理' FROM DUAL
UNION
SELECT '设备', 'S', 'SUCCESS', '已解决' FROM DUAL ) TEMP
LEFT JOIN
(SELECT ZAB."TYPE" , ZAB.STATUS , COUNT(*) CNT
FROM Z_ABNORMAL_BILL zab WHERE STATUS IN ('N','X') AND TO_CHAR(ZAB.CREATED_DATE_TIME,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM') GROUP BY ZAB."TYPE" ,ZAB.STATUS ,TO_CHAR(ZAB.CREATED_DATE_TIME,'YYYY-MM')
UNION
SELECT ZAB."TYPE" , 'SUCCESS' STATUS , COUNT(*) CNT
FROM Z_ABNORMAL_BILL zab WHERE STATUS NOT IN ('N','X') AND TO_CHAR(ZAB.CREATED_DATE_TIME,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM') GROUP BY ZAB."TYPE" ,TO_CHAR(ZAB.CREATED_DATE_TIME,'YYYY-MM') ) T
ON T.TYPE = TEMP.TYPE AND T.STATUS = TEMP.STATUS
ORDER BY TEMP.TYPE DESC,TEMP.STATUS DESC
</select>
<!--设备故障前三-->
<select id="resourceFaultThree" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT DESCRIPTION, QTY
FROM (
SELECT SUBSTR(NT.DESCRIPTION, 0, 4) DESCRIPTION, SUM(1) QTY
FROM Z_ABNORMAL_BILL A
INNER JOIN Z_ABNORMAL_NC_CODE B ON B.ABNORMAL_BILL_BO = A.HANDLE
INNER JOIN NC_CODE NC ON NC.SITE = B.SITE AND NC.NC_CODE = B.NC_CODE
INNER JOIN NC_CODE_T NT ON NT.NC_CODE_BO = NC.HANDLE
WHERE A.TYPE = 'S' AND A.SITE = '1000' AND TO_CHAR(A.CREATED_DATE_TIME,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
GROUP BY SUBSTR(NT.DESCRIPTION, 0, 4)
ORDER BY SUM(1) DESC
) WHERE ROWNUM &lt;= 3
</select>
<!--达成率-->
<select id="completeRate" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT 0 "min", 100 "max", '名称' "label", T.RATE "value",
'%' "unit"
FROM DUAL , (SELECT ROUND( SUM(SO.QTY_DONE) / SUM(SO.QTY_TO_BUILD) , 4 ) * 100 RATE
FROM SHOP_ORDER SO
LEFT JOIN CUSTOM_FIELDS CF ON CF.HANDLE = SO.HANDLE AND CF.ATTRIBUTE = 'FACTORY'
WHERE SITE = '1000'
AND TO_CHAR(SO.PLANNED_COMP_DATE,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
GROUP BY TO_CHAR(PLANNED_COMP_DATE,'YYYY-MM') ) T
</select>
<!--设备运行数-->
<!--设备运行状态数-->
<select id="resourceRunQtyAll" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT X.CNT RUN , Y.CNT IDLE ,Z.CNT "STOP" FROM
(SELECT COUNT(RESRCE) CNT
FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,301' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS != 'RUN')) X ,
(SELECT M.CNT + N.CNT CNT FROM
(SELECT COUNT(RESRCE) CNT FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS = 'FREE') M,
(
SELECT COUNT(RESRCE) CNT FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,4' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS = 'FREE')
) N ) Y ,
(SELECT M.CNT + N.CNT CNT FROM
(SELECT COUNT(RESRCE) CNT FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS IN ('DOW','WARN')) M,
(
SELECT COUNT(RESRCE) CNT FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,5' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS IN ('DOW' ,'WARN'))
) N ) Z
</select>
<!--设备状态:运行中、空闲、停机-->
<select id="resourceQtyRun" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT COUNT(RESRCE) "value"
FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,301' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS != 'RUN')
</select>
<select id="resourceQtyFree" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT M.CNT + N.CNT "value" FROM
(SELECT COUNT(RESRCE) CNT FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS = 'FREE') M,
(
SELECT COUNT(RESRCE) CNT FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,4' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS = 'FREE')
) N
</select>
<select id="resourceQtyDow" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT M.CNT + N.CNT "value" FROM
(SELECT COUNT(RESRCE) CNT FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS IN ('DOW','WARN')) M,
(
SELECT COUNT(RESRCE) CNT FROM RESRCE r
WHERE R.STATUS_BO = 'StatusBO:1000,5' AND R.SITE = '1000'
AND R.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE zrsr WHERE ZRSR.STATUS IN ('DOW' ,'WARN'))
) N
</select>
<!--设备运行状态数-->
<select id="resourceQtyAll" resultType="java.util.HashMap" parameterType="java.util.HashMap">
WITH TEMPA AS (
SELECT COUNT(*) CNT FROM (SELECT DISTINCT ZSD.RESRCE FROM Z_SFC_DISPATCH ZSD
WHERE ZSD.DISPATCH_STATUS IN ('COMPLETE','CANCEL','START')
AND TO_CHAR(ZSD.ACTUAL_START_DATE, 'YYYY-MM-DD') = TO_CHAR(SYSDATE-1 ,'YYYY-MM-DD')
AND ZSD.RESRCE NOT IN (SELECT RESRCE FROM Z_RESOURCE_STATUS_RECEIVE WHERE STATUS = 'RUN'))
) ,
TEMPB AS (SELECT
MAX(CASE WHEN STATUS = 'RUN' THEN QTY ELSE 0 END)RUN,
MAX(CASE WHEN STATUS = 'DOW' THEN QTY ELSE 0 END)"STOP",
MAX(CASE WHEN STATUS = 'WARN' THEN QTY ELSE 0 END)IDLE,
MAX(CASE WHEN STATUS = 'FREE' THEN QTY ELSE 0 END)IDLEA
FROM
( SELECT "STATUS", COUNT(1)QTY FROM Z_RESOURCE_STATUS_RECEIVE GROUP BY "STATUS" ))
SELECT TEMPA.CNT + TEMPB.RUN RUN , TEMPB.STOP STOP , TEMPB.IDLE + TEMPB.IDLEA IDLE
FROM TEMPA, TEMPB
</select>
<!--异常看板-->
<select id="abnormalTypeQty" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT TEMP.* , NVL(T.DID_CNT,0) DID_CNT,NVL(T.SUM_CNT,0) SUM_CNT FROM
( SELECT 'Z' TYPE , '质量异常' TYPE_DESCRIPTION FROM DUAL
UNION
SELECT 'Q' TYPE , '其他异常' TYPE_DESCRIPTION FROM DUAL
UNION
SELECT 'S' TYPE , '设备异常' TYPE_DESCRIPTION FROM DUAL ) TEMP
LEFT JOIN
(SELECT A.TYPE , A.CNT, B.CNT SUM_CNT , A.CNT || '/' || B.CNT DID_CNT FROM
( SELECT ZAB.SITE,"TYPE" ,COUNT("TYPE") CNT FROM Z_ABNORMAL_BILL ZAB
WHERE ZAB.SITE = #{site} AND TO_CHAR(ZAB.CREATED_DATE_TIME + 8/24,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZAB.WORK_CENTER = #{workCenter}
</if>
GROUP BY ZAB."TYPE", TO_CHAR(ZAB.CREATED_DATE_TIME + 8/24,'YYYY-MM'),ZAB.SITE ) A
LEFT JOIN (SELECT SITE,COUNT(*) CNT FROM Z_ABNORMAL_BILL ZAB WHERE TO_CHAR(ZAB.CREATED_DATE_TIME + 8/24,'YYYY-MM') = TO_CHAR(SYSDATE,'YYYY-MM')
GROUP BY SITE ,TO_CHAR(ZAB.CREATED_DATE_TIME + 8/24,'YYYY-MM')) B ON B.SITE = A.SITE
) T
ON T.TYPE = TEMP."TYPE"
ORDER BY TEMP."TYPE" DESC
</select>
<select id="abnormalDataDetails" resultType="java.util.HashMap" parameterType="java.util.HashMap">
SELECT T.* , T.UN_DEAL || '天' UN_DEAL_TIME , UG.DESCRIPTION USER_GROUP_DESCRIPTION FROM
(
SELECT ROW_NUMBER() OVER(ORDER BY ZAB.ABNORMAL_NO) SEQ, ZAB.HANDLE ,
ZAB."TYPE" ,
CASE WHEN ZAB.TYPE = 'Q' THEN '其他'
WHEN ZAB.TYPE = 'Z' THEN '质量'
WHEN ZAB.TYPE = 'S' THEN '设备' END TYPE_LOCALE ,
ZAB.STATUS ,
CASE WHEN ZAB.STATUS = 'N' THEN '新建'
WHEN ZAB.STATUS = 'X' THEN '响应中'
WHEN ZAB.STATUS = 'F' THEN '方案确认'
WHEN ZAB.STATUS = 'J' THEN '纠防确认'
WHEN ZAB.STATUS = 'Q' THEN '取消'
WHEN ZAB.STATUS = 'G' THEN '关闭' END STATUS_LOCALE ,
CASE WHEN ZAB.STATUS = 'F' THEN ZABD.RESOLVE_SEND_USER_GROUP
WHEN ZAB.STATUS = 'J' THEN ZABD.DUTY_SEND_USER_GROUP
WHEN ZAB.STATUS = 'Q' THEN ZAB.CANCEL_SEND_USER_GROUP
ELSE ZAB.REPORT_SEND_USER_GROUP END USER_GROUP ,
CASE WHEN ZAB.STATUS IN ('N' ,'X' ) THEN ROUND(SYSDATE - ZAB.CREATED_DATE_TIME,4)
ELSE 0 END UN_DEAL ,
ZAB.CREATED_DATE_TIME, ZABD.ABNORMAL_METHOD,
CASE WHEN ZABD.ABNORMAL_METHOD = 'X' THEN '线下换料'
WHEN ZABD.ABNORMAL_METHOD = 'S' THEN '试装'
WHEN ZABD.ABNORMAL_METHOD = 'R' THEN '让步放心'
WHEN ZABD.ABNORMAL_METHOD = 'C' THEN '产品报废'
WHEN ZABD.ABNORMAL_METHOD = 'P' THEN '配作'
WHEN ZABD.ABNORMAL_METHOD = 'F' THEN '返修'
WHEN ZABD.ABNORMAL_METHOD = 'CG' THEN '常规维修'
WHEN ZABD.ABNORMAL_METHOD = 'JH' THEN '计划维修'
WHEN ZABD.ABNORMAL_METHOD = 'DX' THEN '大项修' END ABNORMAL_METHOD_LOCALE,
CF.VALUE ITEM_NUMBER , ZAB.RESRCE , R.DESCRIPTION RESOURCE_DESCRIPTION,
ZABD.RESOLVE_DATE_TIME , ZAB.NC_CODE , T.NC_CODE_GATHER , T.DESCRIPTION_GATHER
FROM Z_ABNORMAL_BILL ZAB
LEFT JOIN Z_ABNORMAL_BILL_DISPOSE ZABD ON ZABD.ABNORMAL_BILL_BO = ZAB.HANDLE
LEFT JOIN RESRCE R ON R.RESRCE = ZAB.RESRCE
LEFT JOIN SHOP_ORDER SO ON SO.SHOP_ORDER = ZAB.SHOP_ORDER
LEFT JOIN CUSTOM_FIELDS CF ON CF.HANDLE = SO.HANDLE AND CF."ATTRIBUTE" = 'ITEM_NUMBER'
LEFT JOIN (SELECT ZANC.ABNORMAL_BILL_BO ,LISTAGG(NC.NC_CODE,',') WITHIN GROUP (ORDER BY NC.NC_CODE) NC_CODE_GATHER ,
LISTAGG(NCT.DESCRIPTION ,',') WITHIN GROUP (ORDER BY NCT.DESCRIPTION ) DESCRIPTION_GATHER
FROM Z_ABNORMAL_NC_CODE ZANC
LEFT JOIN NC_CODE NC ON NC.NC_CODE = ZANC.NC_CODE
LEFT JOIN NC_CODE_T NCT ON NCT.NC_CODE_BO = NC.HANDLE
GROUP BY ZANC.ABNORMAL_BILL_BO) T ON T.ABNORMAL_BILL_BO = ZAB.HANDLE
WHERE ZAB.SITE = #{site} AND TO_CHAR(ZAB.CREATED_DATE_TIME + 8/24,'YYYY-MM' ) = TO_CHAR (SYSDATE , 'YYYY-MM')
<if test="workCenter != null and workCenter != ''">
AND ZAB.WORK_CENTER = #{workCenter}
</if>
) T
LEFT JOIN USER_GROUP UG ON UG.USER_GROUP = T.USER_GROUP
ORDER BY T.SEQ
</select>
</mapper>