HJGL_DS/DataBase/版本日志/HJGLDB_DS_2024-08-12_gf.sql

105 lines
5.6 KiB
Transact-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.

ALTER PROC [dbo].[HJGL_sp_rpt_iso_analyze]
@unitNo VARCHAR(400) = NULL,
@isono VARCHAR(100) = NULL,
@steel varchar(50) = NULL,
@projectId NVARCHAR(50) = NULL,
@StartDate datetime =null,
@EndDate datetime =null
AS
/*焊接工作量统计 佘春生修改于2020.03.06*/
SELECT iso.ProjectId,iso.ISO_IsoNo,iso.PressureTestPackageNo,Unit.UnitCode AS bsu_unitcode, --单位代码
Unit.UnitName AS bsu_unitname, --单位名称
'Φ'+cast(cast(ISO_Dia as FLOAT) as nvarchar(50))+'×'+cast(cast(ISO_Sch as FLOAT) as nvarchar(50)) as IsoDesc, --管线主规格
v.ISO_ID,v.total_jot,v.total_din,
ISNULL(v1.finished_total_jot,0) AS finished_total_jot,
ISNULL(v1.finished_total_din,0) AS finished_total_din,v1.maxdate,
ISNULL(v1.total_film,0) AS total_film,
ISNULL(v1.pass_film,0) AS pass_film,
CAST(CASE ISNULL(v1.total_film ,0) WHEN 0 THEN 0
ELSE 1.0*ISNULL(v1.pass_film,0) / (1.0 * v1.total_film) END AS DECIMAL(19,3))
AS passrate, --点口合格率
ISNULL(v2.point_jot,0) AS point_jot,
ISNULL(v2.point_total_film,0) AS point_total_film,
ISNULL(v2.point_pass_film,0) AS point_pass_film,
CAST(CASE ISNULL(v2.point_total_film ,0) WHEN 0 THEN 0
ELSE 1.0*ISNULL(v2.point_pass_film,0) / (1.0 * v2.point_total_film) END AS DECIMAL(19,3))
AS point_passrate, --点口合格率
ISNULL(v3.ext_jot,0) AS ext_jot,
ISNULL(v3.ext_total_film,0) AS ext_total_film,
ISNULL(v3.ext_pass_film,0) AS ext_pass_film,
CAST(CASE ISNULL(v3.ext_total_film ,0) WHEN 0 THEN 0
ELSE 1.0*ISNULL(v3.ext_pass_film,0) / (1.0 * v3.ext_total_film) END AS DECIMAL(19,3))
AS point_passrate, --扩透合格率
(ISNULL(v2.point_jot,0)+ISNULL(v3.ext_jot,0)) AS check_total_jot,
ISNULL(v4.total_repairjot,0) AS total_repairjot,
ISNULL(v5.trust_total_jot,0) AS trust_total_jot,
CAST(CASE ISNULL(v.total_jot,0) WHEN 0 THEN 0
ELSE 1.0*ISNULL(v2.point_jot,0) / (1.0 * v.total_jot) END AS DECIMAL(19,3))
AS trustrate, --委托比例
CAST(CASE ISNULL(v.total_jot,0) WHEN 0 THEN 0
ELSE 1.0*(ISNULL(v3.ext_jot,0) + ISNULL(v2.point_jot,0)) / (1.0 * v.total_jot)
END AS DECIMAL(19,3))
AS checkrate --已探比例
FROM
(SELECT ISO_ID, COUNT(JOT_ID) AS total_jot,SUM(ISNULL(JOT_Size,0)) AS total_din
FROM dbo.HJGL_PW_JointInfo
GROUP BY ISO_ID) v
LEFT JOIN
(SELECT ISO_ID, COUNT(JOT_ID) AS finished_total_jot,SUM(ISNULL(JOT_Size,0)) AS finished_total_din,
max(weldreport.JOT_WeldDate) AS maxdate, SUM(ISNULL(jot.RT_FilmNum,0)) AS total_film,
SUM(ISNULL(jot.RT_FilmNum,0)-ISNULL(jot.RT1_RepairFilmNum,0)) AS pass_film
FROM dbo.HJGL_PW_JointInfo jot
LEFT join HJGL_BO_WeldReportMain AS weldreport on weldreport.DReportID=jot.DReportID
WHERE (weldreport.JOT_WeldDate>=@StartDate or @StartDate is null) and (weldreport.JOT_WeldDate<=@EndDate or @EndDate is null)
AND jot.DReportID is not null
GROUP BY ISO_ID) v1 ON v1.ISO_ID=v.ISO_ID
LEFT JOIN
(SELECT ISO_ID, COUNT(jot.JOT_ID) AS point_jot,SUM(ISNULL(jot.RT_FilmNum,0)) AS point_total_film,
SUM(ISNULL(jot.RT_FilmNum,0)-ISNULL(jot.RT1_RepairFilmNum,0)) AS point_pass_film
FROM dbo.HJGL_PW_JointInfo jot
LEFT join HJGL_BO_WeldReportMain AS weldreport on weldreport.DReportID=jot.DReportID
WHERE (weldreport.JOT_WeldDate>=@StartDate or @StartDate is null) and (weldreport.JOT_WeldDate<=@EndDate or @EndDate is null)
AND jot.DReportID is not NULL AND jot.PointType='点口' or ((select top 1 CH_TrustItemID from HJGL_CH_TrustItem ti where ti.JOT_ID=jot.JOT_ID) is not null and jot.PointType is null)
GROUP BY ISO_ID) v2 ON v2.ISO_ID=v.ISO_ID
LEFT JOIN
(SELECT ISO_ID, COUNT(jot.JOT_ID) AS ext_jot,SUM(ISNULL(jot.RT_FilmNum,0)) AS ext_total_film,
SUM(ISNULL(jot.RT_FilmNum,0)-ISNULL(jot.RT1_RepairFilmNum,0)) AS ext_pass_film
FROM dbo.HJGL_PW_JointInfo jot
LEFT join HJGL_BO_WeldReportMain AS weldreport on weldreport.DReportID=jot.DReportID
WHERE (weldreport.JOT_WeldDate>=@StartDate or @StartDate is null) and (weldreport.JOT_WeldDate<=@EndDate or @EndDate is null)
AND jot.DReportID is not NULL AND jot.PointType='扩透'
GROUP BY ISO_ID) v3 ON v3.ISO_ID=v.ISO_ID
LEFT JOIN
(SELECT jot.ISO_ID, COUNT(distinct trust.JOT_ID) AS trust_total_jot --trust.CH_TrustItemID
FROM dbo.HJGL_CH_TrustItem trust
LEFT join dbo.HJGL_PW_JointInfo AS jot on jot.JOT_ID=trust.JOT_ID
LEFT join HJGL_BO_WeldReportMain AS weldreport on weldreport.DReportID=jot.DReportID
WHERE (weldreport.JOT_WeldDate>=@StartDate or @StartDate is null) and (weldreport.JOT_WeldDate<=@EndDate or @EndDate is null)
AND jot.DReportID is not NULL
GROUP BY jot.ISO_ID) v5 ON v5.ISO_ID=v.ISO_ID
LEFT JOIN
(SELECT ISO_ID,COUNT(DISTINCT(jot.JOT_ID)) AS total_repairjot
FROM dbo.HJGL_PW_JointInfo jot
LEFT join HJGL_BO_WeldReportMain AS weldreport on weldreport.DReportID=jot.DReportID
WHERE (weldreport.JOT_WeldDate>=@StartDate or @StartDate is null) and (weldreport.JOT_WeldDate<=@EndDate or @EndDate is null)
AND jot.DReportID is not NULL
AND(jot.RT1_RepairFilmNum IS NOT NULL OR jot.PTIsRepair1=1 OR jot.MTIsRepair1=1 OR jot.UTIsRepair1=1)
GROUP BY ISO_ID) v4 ON v4.ISO_ID=v.ISO_ID
LEFT JOIN dbo.HJGL_PW_IsoInfo iso ON iso.ISO_ID = v.ISO_ID
LEFT JOIN Base_Unit AS Unit ON Unit.UnitId = iso.BSU_ID
WHERE (iso.ProjectId = @projectId OR @projectId IS NULL)
AND (iso.BSU_ID=@unitno OR @unitno IS NULL)
AND (iso.STE_ID=@steel OR @steel IS NULL)
AND (iso.ISO_IsoNo = @isono OR @isono IS NULL)
GO