430 lines
51 KiB
Transact-SQL
430 lines
51 KiB
Transact-SQL
ALTER TABLE dbo.Welder_WelderQualify ADD IsPrintShow bit NULL
|
||
GO
|
||
EXEC sys.sp_addextendedproperty @name=N'MS_Description', @value=N'打印是否显示' , @level0type=N'SCHEMA',@level0name=N'dbo', @level1type=N'TABLE',@level1name=N'Welder_WelderQualify', @level2type=N'COLUMN',@level2name=N'IsPrintShow'
|
||
GO
|
||
|
||
|
||
ALTER VIEW [dbo].[View_Welder_WelderQualify]
|
||
AS
|
||
/*******焊工资质***********/
|
||
SELECT WelderQualify.WelderQualifyId,
|
||
WelderQualify.WelderId,
|
||
WelderQualify.QualificationItem,
|
||
WelderQualify.LimitDate,
|
||
WelderQualify.CheckDate,
|
||
WelderQualify.WeldingMethodId,
|
||
WelderQualify.MaterialId,
|
||
WelderQualify.WeldingLocationId,
|
||
WelderQualify.ThicknessMin,
|
||
WelderQualify.ThicknessMax,
|
||
WelderQualify.SizesMin,
|
||
WelderQualify.SizesMax,
|
||
(CONVERT(NVARCHAR(10),WelderQualify.ThicknessMin)+'-'+(CONVERT(NVARCHAR(10),WelderQualify.ThicknessMax))) AS Thickness,
|
||
(CONVERT(NVARCHAR(10),WelderQualify.SizesMin)+'-'+(CONVERT(NVARCHAR(10),WelderQualify.SizesMax))) AS Size,
|
||
WelderQualify.Remark,
|
||
Welder.WelderCode,
|
||
Welder.WelderName,
|
||
WeldingMethod.WeldingMethodCode,
|
||
WeldingLocation.WeldingLocationCode,
|
||
WelderQualify.IsPrintShow,
|
||
--Material.SteelType,
|
||
(CASE WelderQualify.MaterialId WHEN '1' THEN '碳钢'
|
||
WHEN '2' THEN '不锈钢'
|
||
WHEN '3' THEN '铬钼钢'
|
||
WHEN '4' THEN '低合金钢'
|
||
WHEN '5' THEN '镍合金钢'
|
||
WHEN '6' THEN '钛合金钢'
|
||
WHEN '7' THEN '其他'
|
||
ELSE '' END) AS SteelTypeName
|
||
FROM Welder_WelderQualify AS WelderQualify
|
||
LEFT JOIN Welder_Welder AS Welder ON Welder.WelderId=WelderQualify.WelderId
|
||
LEFT JOIN Base_WeldingMethod AS WeldingMethod ON WeldingMethod.WeldingMethodId=WelderQualify.WeldingMethodId
|
||
--LEFT JOIN Base_Material AS Material ON Material.MaterialId = WelderQualify.MaterialId
|
||
LEFT JOIN Base_WeldingLocation AS WeldingLocation ON WeldingLocation.WeldingLocationId=WelderQualify.WeldingLocationId
|
||
|
||
|
||
GO
|
||
|
||
|
||
ALTER PROC [dbo].[WeldingQualityWeekMonthReport]
|
||
@startDate datetime = NULL,
|
||
@endDate datetime = NULL,
|
||
@projectType NVARCHAR(50)=NULL,
|
||
@NdtType NVARCHAR(50)=NULL
|
||
AS
|
||
/*焊接质量周月报*/
|
||
SELECT
|
||
Project.ProjectCode as ProjectNo --项目号
|
||
,ISNULL(Totalwelds.Totalwelds,0) AS Totalwelds --焊口总数
|
||
,ISNULL(DBTotal.DBTotal,0) as DBTotal --寸口总数
|
||
,ISNULL(completedwelds.completedwelds,0) AS completedwelds --完成焊口
|
||
,CAST(CASE ISNULL(Totalwelds.Totalwelds,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(completedwelds.completedwelds,0) / (1.0 *Totalwelds.Totalwelds) END AS DECIMAL(19,3))
|
||
AS completedrates --完成率
|
||
,ISNULL(CumulativeDB.CumulativeDB,0) as CumulativeDB --完成寸口数
|
||
,CAST((ISNULL(DBTotal.DBTotal,0)-ISNULL(CumulativeDB.CumulativeDB,0)) AS DECIMAL(19,3))
|
||
AS RemainingDB --剩余寸口数
|
||
,ISNULL(EntrustTestwelds.EntrustTestwelds,0) AS EntrustTestwelds --委托检测焊口
|
||
,ISNULL(Testwelds.Testwelds,0) AS Testwelds --已检测焊口
|
||
,CAST(CASE ISNULL(EntrustTestwelds.EntrustTestwelds,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(Testwelds.Testwelds,0) / (1.0 *EntrustTestwelds.EntrustTestwelds) END AS DECIMAL(19,3))
|
||
AS Testrates -- 检测完成率
|
||
,ISNULL(Rejectwelds.Rejectwelds,0) as Rejectwelds --不合格焊口
|
||
,CAST(CASE ISNULL(Testwelds.Testwelds,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(Rejectwelds.Rejectwelds,0) / (1.0 *Testwelds.Testwelds) END AS DECIMAL(19,3))
|
||
AS Rejectrates -- 不合格率
|
||
,ISNULL(Currentcompletedwelds.Currentcompletedwelds,0) as Currentcompletedwelds --当期完成焊口
|
||
,ISNULL(CurrentTestwelds.CurrentTestwelds,0) as CurrentTestwelds --当期检测焊口
|
||
,ISNULL(CurrentRejectwelds.CurrentRejectwelds,0) as CurrentRejectwelds --当期不合格焊口
|
||
,CAST(CASE ISNULL(CurrentTestwelds.CurrentTestwelds,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(CurrentRejectwelds.CurrentRejectwelds,0) / (1.0 *CurrentTestwelds.CurrentTestwelds) END AS DECIMAL(19,3))
|
||
AS CurrentRejectrates -- 当期不合格率
|
||
FROM Base_Project AS Project
|
||
--焊口总数
|
||
LEFT JOIN (SELECT count(*) as Totalwelds,WeldJoint.ProjectId
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
GROUP BY WeldJoint.ProjectId) AS Totalwelds ON Totalwelds.ProjectId = Project.ProjectId
|
||
----寸口总数
|
||
LEFT JOIN (SELECT SUM(Size) AS DBTotal,WeldJoint.ProjectId
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
GROUP BY WeldJoint.ProjectId) AS DBTotal ON DBTotal.ProjectId =Project.ProjectId
|
||
--完成焊口
|
||
LEFT JOIN (SELECT count(*) AS completedwelds,WeldJoint.ProjectId
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
where WeldJoint.WeldingDailyId is not null
|
||
GROUP BY WeldJoint.ProjectId) AS completedwelds ON completedwelds.ProjectId =Project.ProjectId
|
||
--完成寸口数
|
||
LEFT JOIN (SELECT SUM(Size) AS CumulativeDB,WeldJoint.ProjectId
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
where WeldJoint.WeldingDailyId is not null
|
||
GROUP BY WeldJoint.ProjectId) AS CumulativeDB ON CumulativeDB.ProjectId =Project.ProjectId
|
||
--委托检测焊口
|
||
LEFT JOIN (SELECT Count(*) AS EntrustTestwelds,Trust.ProjectId
|
||
FROM Batch_BatchTrustItem AS TrustItem
|
||
left join Batch_BatchTrust as Trust on TrustItem.TrustBatchId=Trust.TrustBatchId
|
||
WHERE Trust.DetectionTypeId=@NdtType OR @NdtType IS NULL
|
||
GROUP BY Trust.ProjectId) AS EntrustTestwelds ON EntrustTestwelds.ProjectId =Project.ProjectId
|
||
--已检测焊口
|
||
LEFT JOIN (SELECT Count(*) AS Testwelds,NDE.ProjectId
|
||
FROM Batch_NDEItem AS NDEItem
|
||
left join Batch_NDE as NDE on NDEItem.NDEID=NDE.NDEID
|
||
WHERE NDEItem.DetectionTypeId=@NdtType OR @NdtType IS NULL
|
||
GROUP BY NDE.ProjectId) AS Testwelds ON Testwelds.ProjectId =Project.ProjectId
|
||
--不合格焊口
|
||
LEFT JOIN (SELECT Count(*) AS Rejectwelds,NDE.ProjectId
|
||
FROM Batch_NDEItem AS NDEItem
|
||
left join Batch_NDE as NDE on NDEItem.NDEID=NDE.NDEID
|
||
WHERE (NDEItem.DetectionTypeId=@NdtType OR @NdtType IS NULL) AND CheckResult='2'
|
||
GROUP BY NDE.ProjectId) AS Rejectwelds ON Rejectwelds.ProjectId =Project.ProjectId
|
||
--当期完成焊口
|
||
LEFT JOIN (SELECT count(*) AS Currentcompletedwelds,WeldJoint.ProjectId
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
left join dbo.Pipeline_WeldingDaily as WeldingDaily on WeldingDaily.WeldingDailyId=WeldJoint.WeldingDailyId
|
||
where WeldJoint.WeldingDailyId is not null
|
||
and (@startDate is null or WeldingDate>=@startDate) and (@endDate is null or WeldingDate<=@endDate)
|
||
GROUP BY WeldJoint.ProjectId) AS Currentcompletedwelds ON Currentcompletedwelds.ProjectId =Project.ProjectId
|
||
--当期检测焊口
|
||
LEFT JOIN (SELECT Count(*) AS CurrentTestwelds,NDE.ProjectId
|
||
FROM Batch_NDEItem AS NDEItem
|
||
left join Batch_NDE as NDE on NDEItem.NDEID=NDE.NDEID
|
||
where (@startDate is null or NDEDate>=@startDate) and (@endDate is null or NDEDate<=@endDate)
|
||
AND (NDEItem.DetectionTypeId=@NdtType OR @NdtType IS NULL)
|
||
GROUP BY NDE.ProjectId) AS CurrentTestwelds ON CurrentTestwelds.ProjectId =Project.ProjectId
|
||
--当期不合格焊口
|
||
LEFT JOIN (SELECT Count(*) AS CurrentRejectwelds,NDE.ProjectId
|
||
FROM Batch_NDEItem AS NDEItem
|
||
left join Batch_NDE as NDE on NDEItem.NDEID=NDE.NDEID
|
||
where CheckResult='2' AND (NDEItem.DetectionTypeId=@NdtType OR @NdtType IS NULL)
|
||
and (@startDate is null or NDEDate>=@startDate) and (@endDate is null or NDEDate<=@endDate)
|
||
GROUP BY NDE.ProjectId) AS CurrentRejectwelds ON CurrentRejectwelds.ProjectId =Project.ProjectId
|
||
WHERE Project.ProjectTypeId=@projectType OR @projectType IS NULL
|
||
ORDER BY Project.ProjectCode
|
||
|
||
GO
|
||
|
||
|
||
ALTER PROC [dbo].[sp_rpt_MediaComprehensive]
|
||
@unitId NVARCHAR(50) = NULL,
|
||
@workAreaId NVARCHAR(50) = NULL,
|
||
@mediumId NVARCHAR(50) = NULL,
|
||
@projectId NVARCHAR(50) = NULL
|
||
AS
|
||
/*介质综合分析*/
|
||
SELECT ROW_NUMBER() OVER(ORDER BY Unit.UnitCode,WorkArea.WorkAreaCode,Medium.MediumCode) AS Number,
|
||
V.ProjectId,V.UnitId,V.WorkAreaId,V.MediumId
|
||
,Unit.UnitCode --单位代码
|
||
,Unit.UnitName --单位名称
|
||
,WorkArea.WorkAreaCode --工区代号
|
||
,Medium.MediumCode --介质代号
|
||
,Medium.MediumName --介质名称
|
||
,ISNULL(total_jot.total_jot,0) AS total_jot --总焊口数
|
||
,ISNULL(total_sjot.total_sjot,0) AS total_sjot --预制焊口数
|
||
,ISNULL(total_fjot.total_fjot,0) AS total_fjot --安装焊口数
|
||
,ISNULL(finished_jot.finished_jot,0) AS finished_jot --完成焊口数
|
||
,ISNULL(finished_sjot.finished_sjot,0) AS finished_sjot --预制完成焊口数
|
||
,ISNULL(finished_fjot.finished_fjot,0) AS finished_fjot --安装完成焊口数
|
||
,ISNULL(cut_jot.cut_jot,0) AS cut_jot --切除焊口数
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_jot,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_jot.finished_jot,0) /(1.0 * total_jot.total_jot) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finisedrate -- 完成比例
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_jot,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_sjot.finished_sjot,0) /(1.0 * total_jot.total_jot) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finisedrate_s -- 预制完成比例
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_jot,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_fjot.finished_fjot,0) /(1.0 * total_jot.total_jot) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finisedrate_f -- 安装完成比例
|
||
,CAST(ISNULL(total_jot.total_din,0) AS DECIMAL(19,2)) AS total_din --总达因
|
||
,CAST(ISNULL(total_sjot.total_sdin,0) AS DECIMAL(19,2)) AS total_sdin --预制达因
|
||
,CAST(ISNULL(total_fjot.total_fdin,0) AS DECIMAL(19,2)) AS total_fdin --安装达因
|
||
|
||
,CAST(ISNULL(finished_jot.finished_din,0) AS DECIMAL(19,2)) AS finished_din --完成总达因
|
||
,CAST(ISNULL(finished_sjot.finished_sdin,0) AS DECIMAL(19,2)) AS finished_sdin --预制完成总达因
|
||
,CAST(ISNULL(finished_fjot.finished_fdin,0) AS DECIMAL(19,2)) AS finished_fdin --安装完成总达因
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_din,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_jot.finished_din,0) /(1.0 * total_jot.total_din) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finishedrate_din --达因完成比例
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_din,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_sjot.finished_sdin,0) /(1.0 * total_jot.total_din) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finishedrate_sdin --达因预制完成比例
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_jot.total_din,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(finished_fjot.finished_fdin,0) /(1.0 * total_jot.total_din) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS finishedrate_fdin --达因安装完成比例
|
||
,ISNULL(total_film.total_film,0) AS total_film --总拍片数
|
||
,ISNULL(total_film.pass_film,0) AS pass_film --合格片数
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(total_film.total_film,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(total_film.pass_film,0) /(1.0 * total_film.total_film) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS passfilm_rate --合格率
|
||
|
||
,ISNULL(ext_totalfilm.ext_totalfilm,0) AS ext_totalfilm --扩透总数
|
||
,ISNULL(ext_totalfilm.ext_passfilm,0) AS ext_passfilm --扩透合格总数
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(ext_totalfilm.ext_totalfilm,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(ext_totalfilm.ext_passfilm,0) /(1.0 * ext_totalfilm.ext_totalfilm) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS ext_passrate --扩透合格率
|
||
|
||
,ISNULL(point_totalfilm.point_totalfilm,0) AS point_totalfilm --点口总数
|
||
,ISNULL(point_totalfilm.point_passfilm,0) AS point_passfilm --点口合格总数
|
||
,CONVERT(NVARCHAR(10),((CAST(CASE ISNULL(point_totalfilm.point_totalfilm,0) WHEN 0 THEN 0
|
||
ELSE 1.0*ISNULL(point_totalfilm.point_passfilm,0) /(1.0 * point_totalfilm.point_totalfilm) END AS DECIMAL(19,3)))*100))+'%'
|
||
AS point_passrate --点口合格率
|
||
|
||
,ISNULL(cut_totalfilm.cut_totalfilm,0) AS cut_totalfilm --切除总数
|
||
,ISNULL(cut_totalfilm.cut_passfilm,0) AS cut_passfilm --切除合格总数
|
||
,ISNULL(trust_total_jot.trust_total_jot,0) AS trust_total_jot ---委托总数
|
||
,ISNULL(trust_ext_total_jot.trust_ext_total_jot,0) AS trust_ext_total_jot ---委托扩透总数
|
||
,(ISNULL(trust_total_jot.trust_total_jot,0) - ISNULL(trust_ext_total_jot.trust_ext_total_jot,0))
|
||
AS trust_point_total_jot ---委托点口总数
|
||
,(ISNULL(ext_totalfilm.check_point_total_jot1,0) + ISNULL(point_totalfilm.check_point_total_jot2,0))
|
||
AS check_point_total_jot --已探口数
|
||
,ISNULL(repair_jot.repair_jot,0) AS repair_jot ---返修口数
|
||
FROM
|
||
(SELECT pipeline.ProjectId
|
||
,pipeline.UnitId
|
||
,pipeline.WorkAreaId
|
||
,pipeline.MediumId
|
||
FROM Pipeline_Pipeline AS pipeline
|
||
WHERE (pipeline.ProjectId = @projectId OR @projectId IS NULL)
|
||
AND (pipeline.UnitId = @unitId OR @unitId IS NULL)
|
||
AND (pipeline.WorkAreaId = @workAreaId OR @workAreaId IS NULL)
|
||
AND (pipeline.MediumId = @mediumId OR @mediumId IS NULL)
|
||
GROUP BY pipeline.ProjectId ,pipeline.UnitId,pipeline.WorkAreaId,pipeline.MediumId) AS V
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS total_jot --总焊口数
|
||
,SUM(size) AS total_din --总达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS total_jot
|
||
ON total_jot.ProjectId = V.ProjectId AND total_jot.UnitId = V.UnitId AND total_jot.WorkAreaId = V.WorkAreaId AND total_jot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS total_sjot --预制焊口数
|
||
,SUM(size) AS total_sdin --预制达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
where JointArea='S'
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS total_sjot
|
||
ON total_sjot.ProjectId = V.ProjectId AND total_sjot.UnitId = V.UnitId AND total_sjot.WorkAreaId = V.WorkAreaId AND total_sjot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS total_fjot --安装焊口数
|
||
,SUM(size) AS total_fdin --安装达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
where JointArea='F'
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS total_fjot
|
||
ON total_fjot.ProjectId = V.ProjectId AND total_fjot.UnitId = V.UnitId AND total_fjot.WorkAreaId = V.WorkAreaId AND total_fjot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS finished_jot --完成焊口数
|
||
,SUM(DoneDin) AS finished_din --完成总达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
where WeldingDailyId IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS finished_jot
|
||
ON finished_jot.ProjectId = V.ProjectId AND finished_jot.UnitId = V.UnitId AND finished_jot.WorkAreaId = V.WorkAreaId AND finished_jot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS finished_sjot --预制完成焊口数
|
||
, SUM(donedin) AS finished_sdin --预制完成总达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
where WeldingDailyId IS NOT NULL and JointArea='S'
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS finished_sjot
|
||
ON finished_sjot.ProjectId = V.ProjectId AND finished_sjot.UnitId = V.UnitId AND finished_sjot.WorkAreaId = V.WorkAreaId AND finished_sjot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS finished_fjot --安装完成焊口数
|
||
,SUM(donedin) AS finished_fdin --安装完成总达因
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
where WeldingDailyId IS NOT NULL and JointArea='F'
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS finished_fjot
|
||
ON finished_fjot.ProjectId = V.ProjectId AND finished_fjot.UnitId = V.UnitId AND finished_fjot.WorkAreaId = V.WorkAreaId AND finished_fjot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS cut_jot --切除口数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Batch_PointBatchItem
|
||
LEFT JOIN Pipeline_WeldJoint jot ON Batch_PointBatchItem.WeldJointId =jot.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE Batch_PointBatchItem.CutDate IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS cut_jot
|
||
ON cut_jot.ProjectId = V.ProjectId AND cut_jot.UnitId = V.UnitId AND cut_jot.WorkAreaId = V.WorkAreaId AND cut_jot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, SUM(TotalFilm) AS total_film --总拍片数
|
||
,SUM(PassFilm) AS pass_film --合格片数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Pipeline_WeldJoint AS jot
|
||
LEFT JOIN Batch_PointBatchItem ON Batch_PointBatchItem.WeldJointId = jot.WeldJointId
|
||
LEFT JOIN Batch_BatchTrustItem ON Batch_BatchTrustItem.PointBatchItemId = Batch_PointBatchItem.PointBatchItemId
|
||
LEFT JOIN Batch_NDEItem ON Batch_NDEItem.TrustBatchItemId = Batch_BatchTrustItem.TrustBatchItemId
|
||
LEFT JOIN Batch_NDE ON Batch_NDE.NDEID = Batch_NDEItem.NDEID
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE Batch_NDEItem.NDEItemID IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId ) AS total_film
|
||
ON total_film.ProjectId = V.ProjectId AND total_film.UnitId = V.UnitId AND total_film.WorkAreaId = V.WorkAreaId AND total_film.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, SUM(TotalFilm) AS ext_totalfilm
|
||
,SUM(PassFilm) AS ext_passfilm --扩透合格片数
|
||
,COUNT(*) AS check_point_total_jot1 --总已探数1
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Batch_NDEItem
|
||
LEFT JOIN Batch_BatchTrustItem ON Batch_NDEItem.TrustBatchItemId =Batch_BatchTrustItem.TrustBatchItemId
|
||
LEFT JOIN Batch_PointBatchItem ON Batch_PointBatchItem.PointBatchItemId =Batch_BatchTrustItem.PointBatchItemId
|
||
LEFT JOIN Pipeline_WeldJoint jot ON jot.WeldJointId=Batch_PointBatchItem.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE Batch_PointBatchItem.PointState='2' AND Batch_PointBatchItem.PointDate IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS ext_totalfilm
|
||
ON ext_totalfilm.ProjectId = V.ProjectId AND ext_totalfilm.UnitId = V.UnitId AND ext_totalfilm.WorkAreaId = V.WorkAreaId AND ext_totalfilm.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, SUM(TotalFilm) AS point_totalfilm --点口总数
|
||
,SUM(PassFilm) AS point_passfilm --点口合格总数
|
||
,COUNT(*) AS check_point_total_jot2 --已探口数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Batch_NDEItem
|
||
LEFT JOIN Batch_BatchTrustItem ON Batch_NDEItem.TrustBatchItemId =Batch_BatchTrustItem.TrustBatchItemId
|
||
LEFT JOIN Batch_PointBatchItem ON Batch_PointBatchItem.PointBatchItemId =Batch_BatchTrustItem.PointBatchItemId
|
||
LEFT JOIN Pipeline_WeldJoint jot ON jot.WeldJointId=Batch_PointBatchItem.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE Batch_PointBatchItem.PointState='1' AND Batch_PointBatchItem.PointDate IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS point_totalfilm
|
||
ON point_totalfilm.ProjectId = V.ProjectId AND point_totalfilm.UnitId = V.UnitId AND point_totalfilm.WorkAreaId = V.WorkAreaId AND point_totalfilm.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, SUM(TotalFilm) AS cut_totalfilm --切除总数
|
||
,SUM(PassFilm) AS cut_passfilm --切除合格总数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM (SELECT WeldJointId FROM Batch_PointBatchItem
|
||
WHERE Batch_PointBatchItem.CutDate IS NOT NULL) AS PointBatchItem
|
||
LEFT JOIN Pipeline_WeldJoint jot ON jot.WeldJointId=PointBatchItem.WeldJointId
|
||
LEFT JOIN Batch_NDEItem ON PointBatchItem.WeldJointId = jot.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS cut_totalfilm
|
||
ON cut_totalfilm.ProjectId = V.ProjectId AND cut_totalfilm.UnitId = V.WorkAreaId AND cut_totalfilm.WorkAreaId = V.WorkAreaId AND cut_totalfilm.MediumId = V.MediumId
|
||
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS trust_total_jot ---委托口数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM (SELECT Batch_PointBatchItem.WeldJointId FROM Batch_BatchTrustItem
|
||
LEFT JOIN Batch_PointBatchItem ON Batch_BatchTrustItem.PointBatchItemId =Batch_PointBatchItem.PointBatchItemId) AS TrustBatchItem
|
||
LEFT JOIN Pipeline_WeldJoint jot ON jot.WeldJointId= TrustBatchItem.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS trust_total_jot
|
||
ON trust_total_jot.ProjectId = V.ProjectId AND trust_total_jot.UnitId = V.UnitId AND trust_total_jot.WorkAreaId = V.WorkAreaId AND trust_total_jot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS trust_ext_total_jot ---委托扩透总数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Batch_BatchTrustItem AS TrustBatchItem
|
||
LEFT JOIN Batch_PointBatchItem AS PointBatchItem ON PointBatchItem.PointBatchItemId = TrustBatchItem.PointBatchItemId
|
||
LEFT JOIN Pipeline_WeldJoint AS jot ON PointBatchItem.WeldJointId = jot.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE PointBatchItem.PointState ='2' AND PointBatchItem.PointDate IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS trust_ext_total_jot
|
||
ON trust_ext_total_jot.ProjectId = V.ProjectId AND trust_ext_total_jot.UnitId = V.UnitId AND trust_ext_total_jot.WorkAreaId = V.WorkAreaId AND trust_ext_total_jot.MediumId = V.MediumId
|
||
|
||
LEFT JOIN (SELECT jot.ProjectId, COUNT(*) AS repair_jot --返修口数
|
||
,iso.UnitId,iso.WorkAreaId,iso.MediumId
|
||
FROM Batch_BatchTrustItem AS TrustBatchItem
|
||
LEFT JOIN Batch_PointBatchItem AS PointBatchItem ON PointBatchItem.PointBatchItemId = TrustBatchItem.PointBatchItemId
|
||
LEFT JOIN Pipeline_WeldJoint AS jot ON PointBatchItem.WeldJointId = jot.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS iso ON jot.PipelineId=iso.PipelineId
|
||
WHERE PointBatchItem.RepairDate IS NOT NULL
|
||
GROUP BY jot.ProjectId, iso.UnitId,iso.WorkAreaId,iso.MediumId) AS repair_jot
|
||
ON repair_jot.ProjectId = V.ProjectId AND repair_jot.UnitId = V.UnitId AND repair_jot.WorkAreaId = V.WorkAreaId AND repair_jot.MediumId = V.MediumId
|
||
LEFT JOIN Base_Medium AS Medium ON Medium.MediumId = v.MediumId
|
||
LEFT JOIN Project_WorkArea AS WorkArea ON WorkArea.WorkAreaId = v.WorkAreaId
|
||
LEFT JOIN Base_Unit AS Unit ON Unit.UnitId = v.UnitId
|
||
|
||
GO
|
||
|
||
|
||
|
||
ALTER VIEW [dbo].[View_GenerateTrust]
|
||
AS
|
||
-------正常点口生成委托-----------
|
||
SELECT point.ProjectId,point.InstallationId,pipe.WorkAreaId ,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId,'1' AS PointState,CAST(0 AS BIT) AS IsCheckRepair, NULL AS TrustBatchCode
|
||
FROM dbo.Batch_PointBatchItem pointItem
|
||
LEFT JOIN dbo.Batch_PointBatch point ON point.PointBatchId = pointItem.PointBatchId
|
||
LEFT JOIN dbo.Batch_BatchTrustItem trustItem ON trustItem.PointBatchItemId = pointItem.PointBatchItemId
|
||
LEFT JOIN dbo.Pipeline_WeldJoint jot ON jot.WeldJointId = pointItem.WeldJointId
|
||
LEFT JOIN dbo.Pipeline_Pipeline pipe ON pipe.PipelineId = jot.PipelineId
|
||
WHERE pointItem.PointState ='1' AND point.EndDate IS NOT NULL AND pointItem.CutDate IS NULL
|
||
AND (pointItem.IsBuildTrust IS NULL OR pointItem.IsBuildTrust=0)
|
||
AND (point.IsTrust=0 OR trustItem.TrustBatchItemId IS NULL)
|
||
AND pointItem.IsCheckRepair=0
|
||
GROUP BY point.ProjectId,point.InstallationId,pipe.WorkAreaId,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId
|
||
|
||
UNION ALL
|
||
-------扩透生成委托-----------
|
||
SELECT point.ProjectId,point.InstallationId,pipe.WorkAreaId ,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId,'2' AS PointState,CAST(0 AS BIT) AS IsCheckRepair, trust.TrustBatchCode
|
||
FROM dbo.Batch_PointBatchItem pointItem
|
||
LEFT JOIN dbo.Batch_PointBatch point ON point.PointBatchId = pointItem.PointBatchId
|
||
LEFT JOIN dbo.Pipeline_WeldJoint jot ON jot.WeldJointId = pointItem.WeldJointId
|
||
LEFT JOIN dbo.Pipeline_Pipeline pipe ON pipe.PipelineId = jot.PipelineId
|
||
LEFT JOIN dbo.Batch_BatchTrustItem trustItem ON trustItem.PointBatchItemId=pointItem.ToPointBatchItemId
|
||
LEFT JOIN dbo.Batch_BatchTrust trust ON trust.TrustBatchId = trustItem.TrustBatchId
|
||
WHERE pointItem.PointState ='2' AND point.EndDate IS NOT NULL
|
||
AND pointItem.CutDate IS NULL AND (pointItem.IsBuildTrust IS NULL OR pointItem.IsBuildTrust=0)
|
||
AND (point.IsTrust=0 OR trustItem.TrustBatchItemId IS NULL)
|
||
GROUP BY point.ProjectId,point.InstallationId,pipe.WorkAreaId,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId,trust.TrustBatchCode
|
||
|
||
UNION ALL
|
||
-------返修生成委托-----------
|
||
SELECT point.ProjectId,point.InstallationId,pipe.WorkAreaId ,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId,'1' AS PointState,CAST(1 AS BIT) AS IsCheckRepair, trust.TrustBatchCode
|
||
FROM dbo.Batch_PointBatchItem pointItem
|
||
LEFT JOIN dbo.Batch_PointBatch point ON point.PointBatchId = pointItem.PointBatchId
|
||
LEFT JOIN dbo.Pipeline_WeldJoint jot ON jot.WeldJointId = pointItem.WeldJointId
|
||
LEFT JOIN dbo.Pipeline_Pipeline pipe ON pipe.PipelineId = jot.PipelineId
|
||
LEFT JOIN dbo.Batch_BatchTrustItem trustItem ON trustItem.PointBatchItemId=pointItem.PointBatchItemId
|
||
LEFT JOIN dbo.Batch_BatchTrust trust ON trust.TrustBatchId = trustItem.TrustBatchId
|
||
WHERE pointItem.PointState ='1' AND pointItem.IsCheckRepair=1 AND point.EndDate IS NOT NULL
|
||
AND pointItem.CutDate IS NULL AND (pointItem.IsBuildTrust IS NULL OR pointItem.IsBuildTrust=0) AND point.IsTrust=0
|
||
GROUP BY point.ProjectId,point.InstallationId,pipe.WorkAreaId,point.UnitId,point.DetectionTypeId,
|
||
jot.PipelineId,trust.TrustBatchCode
|
||
|
||
GO
|
||
|