INSERT INTO dbo.Sys_Menu VALUES('D0B76B55-E322-40BE-A4FD-F327F5435177','绩效报告','Performance Report','Evaluation/PerformanceReport.aspx',40,'9CC692E1-B425-4FFD-B708-FFF59E384B19') GO INSERT INTO Sys_ButtonToMenu(ButtonToMenuId,MenuId,ButtonName,ButtonEnName,SortIndex) VALUES('76A8E960-7F32-4DF7-84E0-B234B61B2DF1','D0B76B55-E322-40BE-A4FD-F327F5435177','导出','Export',5) GO ALTER TABLE dbo.FC_ContractManagement ADD OccurDate DATETIME NULL GO ALTER TABLE dbo.FC_ContractManagement ADD BycDept NVARCHAR(50) NULL GO ALTER TABLE dbo.EMC_Punishment ADD ViolationRelatedSes NVARCHAR(50) GO CREATE TABLE [dbo].[SyncDataUserLogs]( [id] [int] IDENTITY(1,1) NOT NULL, [batchNo] [nvarchar](50) NOT NULL, [dataType] [int] NOT NULL, [depatId] [nvarchar](50) NULL, [userId] [nvarchar](50) NULL, [createdTime] [datetime] NULL, [IsSuccess] [bit] NULL, [Remark] [nvarchar](max) NULL, CONSTRAINT [PK__SyncData__3213E83F85A6E9AD] PRIMARY KEY CLUSTERED ( [id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY] GO CREATE PROCEDURE [dbo].[SpGetNewCode3] @tableName VARCHAR(50),/*表名*/ @columnName VARCHAR(50),/*列名*/ @prefix VARCHAR(50),/*流水号编码前缀*/ @returnVal NVARCHAR(100) OUTPUT AS /*获取一个新的流水号(后三位上增加)*/ DECLARE @sql NVARCHAR(500), @old NVARCHAR(50), @newid VARCHAR(50), @prefix2 NVARCHAR(100), @maxId NVARCHAR(50)/*已分配的最大值*/ SET @prefix2= REPLACE(@prefix, @columnName, '') SELECT @sql=N'SELECT @maxId=MAX('+@columnName+') from '+@tableName+' where ' + @columnName + ' like ' + '''' + @prefix2 + '%''' EXEC sp_executesql @sql, N'@maxId nvarchar(50) OUTPUT', @maxId OUTPUT SET @old=@maxId IF(@old IS NULL) BEGIN SET @newid=@prefix+'001' END ELSE BEGIN SET @newid = (SELECT MAX(RIGHT(@old,3)))+1 SET @newid = @prefix +RIGHT('000'+@newid,3) END SET @returnVal=@newid GO ALTER VIEW [dbo].[View_EMC_Punishment] AS /*********扣款视图**********/ SELECT punish.PunishmentId,punish.PunishDate,punish.FO_NO,punish.SES_No,punish.Location,punish.Description,punish.Company, punish.Individual, (ISNULL(punish.Company,0)+ISNULL(punish.Individual,0)) AS Backcharge, punish.CompletionDate,punish.PunishDate AS PunishTime, (CASE WHEN punish.ViolationDegree='1' THEN '一般违章' WHEN punish.ViolationDegree='2' THEN '严重违章' WHEN punish.ViolationDegree='3' THEN '零容忍违章' END) AS ViolationDegree, (CASE WHEN con.Contractor IS NULL THEN con.ContractorCN WHEN con.ContractorCN IS NULL THEN con.Contractor ELSE con.Contractor+con.ContractorCN END)AS Contractor, datas.Contractor AS ContractorId,dis.Discipline AS DisciplineEn,dis.DisciplineCN,con.Contractor AS ContractorEn,con.ContractorCN, (CASE WHEN dis.Discipline IS NULL THEN dis.DisciplineCN WHEN dis.DisciplineCN IS NULL THEN dis.Discipline ELSE dis.Discipline+dis.DisciplineCN END) AS Discipline, datas.Contract_Admin AS Contract_AdminId, u.UserName AS Contract_Admin, u2.UserName AS Main_Coordinator,mcdep.DepartName AS MCDept, u3.UserName AS User_Representative, bycDep.DepartName AS BYCRU, u4.UserName AS Violation_Inspector_Name,viDep.DepartName AS InspectionDep,punish.BYC_RU,punish.Violation_Inspector,punish.ViolationRelatedSes,punish.Flag FROM dbo.EMC_Punishment punish LEFT JOIN dbo.FC_SESRelatedData datas ON datas.FO_NO = punish.FO_NO LEFT JOIN dbo.Base_Contractor AS con ON con.ContractorId = datas.Contractor LEFT JOIN dbo.Base_Discipline AS dis ON dis.DisciplineId = datas.DisciplineId LEFT JOIN dbo.Sys_User AS u ON u.UserId = datas.Contract_Admin LEFT JOIN dbo.Sys_User AS u2 ON u2.UserId = datas.Main_Coordinator LEFT JOIN dbo.Sys_User AS u3 ON u3.UserId=datas.User_Representative LEFT JOIN dbo.Base_Depart mcdep ON mcdep.DepartId = u2.DepartId LEFT JOIN dbo.Base_Depart bycDep ON bycdep.DepartId=punish.BYC_RU LEFT JOIN dbo.Sys_User AS u4 ON u4.UserId=punish.Violation_Inspector LEFT JOIN dbo.Base_Depart viDep ON viDep.DepartId=u4.DepartId GO CREATE VIEW [dbo].[View_FC_ContractManagement] AS SELECT cm.OccurDate,fc.FO_NO,dis.Discipline AS DisciplineEn,dis.DisciplineCN,con.Contractor AS ContractorEn,con.ContractorCN, (CASE WHEN con.Contractor IS NULL THEN con.ContractorCN WHEN con.ContractorCN IS NULL THEN con.Contractor ELSE con.Contractor+con.ContractorCN END)AS Contractor, (CASE WHEN dis.Discipline IS NULL THEN dis.DisciplineCN WHEN dis.DisciplineCN IS NULL THEN dis.Discipline ELSE dis.Discipline+dis.DisciplineCN END) AS Discipline, cm.Remark,ftype.FileType,u.UserName AS Contract_Admin, u2.UserName AS Main_Coordinator,mcdep.DepartName AS MCDept, u3.UserName AS User_Representative, bycDep.DepartCode AS BycDept FROM dbo.FC_ContractManagement cm LEFT JOIN dbo.FC_SESRelatedData fc ON fc.ID = cm.FC_ID LEFT JOIN dbo.Base_Discipline AS dis ON dis.DisciplineId = fc.DisciplineId LEFT JOIN dbo.Base_Contractor AS con ON con.ContractorId = fc.Contractor LEFT JOIN dbo.Base_FileType ftype ON ftype.FileTypeId = cm.FileTypeId LEFT JOIN dbo.Sys_User AS u ON u.UserId = fc.Contract_Admin LEFT JOIN dbo.Sys_User AS u2 ON u2.UserId = fc.Main_Coordinator LEFT JOIN dbo.Sys_User AS u3 ON u3.UserId=fc.User_Representative LEFT JOIN dbo.Base_Depart mcdep ON mcdep.DepartId = u2.DepartId LEFT JOIN dbo.Base_Depart bycDep ON bycDep.DepartId=cm.BycDept GO CREATE VIEW [dbo].[View_FC_Contractor] AS SELECT (CASE WHEN con.Contractor IS NULL THEN con.ContractorCN WHEN con.ContractorCN IS NULL THEN con.Contractor ELSE con.Contractor+con.ContractorCN END)AS Contractor, fc.FO_NO,fc.FC_Status,fc.Expire_Date FROM dbo.FC_SESRelatedData fc LEFT JOIN dbo.Base_Contractor AS con ON con.ContractorId = fc.Contractor GO ALTER PROCEDURE [dbo].[FN_OverviewReport] @StartTime DATETIME, @EndTime DATETIME AS BEGIN SELECT tab.FO_NO,tab.Work_Description,tab.Contractor,tab.Main_Coordinator,tab.UserNum,tab.EvaluateNum, --部门已评人数Score1 tab.DepYpScore1,tab.DepZpScore1, --部门已评人数Score2 tab.DepYpScore2,tab.DepZpScore2, --部门已评人数Score3 tab.DepYpScore3,tab.DepZpScore3, --部门已评人数Score4 tab.DepYpScore4,tab.DepZpScore4, --部门已评人数Score5 tab.DepYpScore5,tab.DepZpScore5, --部门已评人数Score6 tab.DepYpScore6,tab.DepZpScore6, --CONVERT(DECIMAL(9,1), --(ISNULL(tab.AvgEvaScore1,0)+ --ISNULL(tab.AvgEvaScore2,0)+ --ISNULL(tab.AvgEvaScore3,0)+ --ISNULL(tab.AvgEvaScore4,0)+ --ISNULL(tab.AvgEvaScore5,0)+ --ISNULL(tab.AvgEvaScore6,0)+ --ISNULL(tab.CTSSAvgScore,0)+ --ISNULL(tab.CTSCAvgScore,0) + --ISNULL(tab.MainCoordinatorAvgScore,0) + --ISNULL(tab.UserRepresentativeAvgScore,0) + --ISNULL(tab.CTSTAvgScore,0) + --ISNULL(tab.CTEDAvgScore,0)+ --ISNULL(tab.TimelyAvgSocre,0)+ --ISNULL(tab.HonestyAvgScore,0))) --AS Total, --用户占60%,部门占40% CONVERT(DECIMAL(9,1),((CASE WHEN tab.EvaluateNum>0 THEN (ISNULL(tab.AvgEvaScore1,0)+ ISNULL(tab.AvgEvaScore2,0)+ ISNULL(tab.AvgEvaScore3,0)+ ISNULL(tab.AvgEvaScore4,0)+ ISNULL(tab.AvgEvaScore5,0)+ ISNULL(tab.AvgEvaScore6,0))*60/60 ELSE 0 END)+ (CASE WHEN ((CASE WHEN tab.CTSSAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTSCAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.MainCoordinatorAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.UserRepresentativeAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.CTSTAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTEDAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.TimelyAvgSocre IS NOT NULL THEN 5 ELSE 0 END)+ (CASE WHEN tab.HonestyAvgScore IS NOT NULL THEN 5 ELSE 0 END))>0 THEN ((ISNULL(tab.CTSSAvgScore,0)+ ISNULL(tab.CTSCAvgScore,0)+ISNULL(tab.MainCoordinatorAvgScore,0)+ ISNULL(tab.UserRepresentativeAvgScore,0)+ISNULL(tab.CTSTAvgScore,0)+ISNULL(tab.CTEDAvgScore,0)+ ISNULL(tab.TimelyAvgSocre,0)+ISNULL(tab.HonestyAvgScore,0))*40) / ((CASE WHEN tab.CTSSAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTSCAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.MainCoordinatorAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.UserRepresentativeAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.CTSTAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTEDAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.TimelyAvgSocre IS NOT NULL THEN 5 ELSE 0 END)+ (CASE WHEN tab.HonestyAvgScore IS NOT NULL THEN 5 ELSE 0 END)) ELSE 0 END) )) AS Total, (CASE WHEN (CONVERT(DECIMAL(18,2),(tab.EvaluateNum*6)+DepYpScore1+DepYpScore2+DepYpScore3+DepYpScore4+DepYpScore5+DepYpScore6)/ CONVERT(DECIMAL(18,2),(tab.UserNum*6)+DepZpScore1+DepZpScore2+DepZpScore3+DepZpScore4+DepZpScore5+DepZpScore6 ))>1 THEN 100.00 ELSE CONVERT(DECIMAL(18,2),(CONVERT(DECIMAL(18,2),(tab.EvaluateNum*6)+DepYpScore1+DepYpScore2+DepYpScore3+DepYpScore4+DepYpScore5+DepYpScore6)/ CONVERT(DECIMAL(18,2),(tab.UserNum*6)+DepZpScore1+DepZpScore2+DepZpScore3+DepZpScore4+DepZpScore5+DepZpScore6 ))*100) END) AS Participation_Rate,--参与率 tab.AvgEvaScore1,--评价均分(工作准备) tab.TotalAvgScore1,--总平均分 tab.AvgEvaScore2, tab.TotalAvgScore2, tab.AvgEvaScore3, tab.TotalAvgScore3, tab.AvgEvaScore4, tab.TotalAvgScore4, tab.AvgEvaScore5, tab.TotalAvgScore5, tab.AvgEvaScore6, tab.TotalAvgScore6, tab.TimelyAvgSocre, tab.HonestyAvgScore, tab.CTSSAvgScore, tab.CTSCAvgScore, tab.MainCoordinatorAvgScore, tab.UserRepresentativeAvgScore, tab.CTSTAvgScore, tab.CTEDAvgScore, FORMAT(DATEADD(MONTH,-1,@StartTime),'yyyy-MM') AS ReportMonth FROM (SELECT a.FO_NO,(ISNULL(dis.Discipline,'')+ISNULL(dis.DisciplineCN,'')) AS Work_Description,(d.Contractor+d.ContractorCN)AS Contractor,u.UserName AS Main_Coordinator, --总评价数 COUNT(DISTINCT(Requisitioner)) AS UserNum, --用户已评人数 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='User' AND ISNULL(Remark,'')!='Auto') AS EvaluateNum, --部门已评人数score1 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score1>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore1, --部门总评人数score1 (SELECT COUNT(1) FROM Sys_User WHERE RoleId='39e35a17-8fa2-447c-b1da-bf92bff36ad4') AS DepZpScore1, --部门已评人数score2 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score2>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore2, --部门总评人数score2 (SELECT COUNT(1) FROM Sys_User WHERE RoleId='b76dec7a-ba1c-46f1-8859-ece4b18252b1') AS DepZpScore2, --部门已评人数score3 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score3>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore3, --部门总评人数score3 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.Main_Coordinator) AS DepZpScore3, --部门已评人数score4 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score4>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore4, --部门总评人数score4 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.User_Representative) AS DepZpScore4, --部门已评人数score5 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score5>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore5, --部门总评人数score4 (SELECT COUNT(1) FROM Sys_User WHERE RoleId='111eb3c5-a3b7-49de-a40b-e5bb3fd10944') AS DepZpScore5, --部门已评人数score6 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score6>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore6, --部门总评人数score4 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.Contract_Admin) AS DepZpScore6, --工作准备Preparation 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score1>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore1, --工作准备Preparation 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore1, --工作表现Performance 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score2>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore2, --工作表现Performance 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore2, --EHSS管理 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score3>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore3, --EHSS管理 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore3, --质量控制Quality Control 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score4>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore4, --质量控制Quality Control 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore4, --时间管理Timeline Management 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score5>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore5, --时间管理Timeline Management 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore5, --文档管理Documentation 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score6>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore6, --文档管理Documentation 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore6, --"及时性Timely submission"平均分 (CASE WHEN a.FOTypeId='e3dd9ecc-4474-4e94-85ff-22dc073fd8b0' THEN --FC (SELECT CONVERT(DECIMAL(18,2),AVG(f.Timely)) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) WHEN a.FOTypeId='eb846026-639f-4063-8d3d-a253905ddfe0' THEN --TAR (SELECT CONVERT(DECIMAL(18,2),AVG(f.Timely)) FROM dbo.TAR_HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) WHEN a.FOTypeId='58544360-5d26-4358-8459-928aa5f6e3ab' AND (SELECT COUNT(*) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime)>0 THEN --OEM CONVERT(DECIMAL(18,2),5.0) END) AS TimelyAvgSocre, --"诚实度Honesty"平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Honesty)) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) AS HonestyAvgScore, --CTS/S (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score1>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSSAvgScore, --CTS/C (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score2>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSCAvgScore, --Main Coordinator (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score3>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS MainCoordinatorAvgScore, --User Representative (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score4>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS UserRepresentativeAvgScore, --CTM/T (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score5>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSTAvgScore, --CTE/D (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score6>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTEDAvgScore --用户总分 --(SELECT ISNULL(CONVERT(DECIMAL(18,2),AVG(f.Score1+f.Score2+f.Score3+f.Score4+f.Score5+f.Score6+f.Score7)),0.00)FROM FC_Score AS f WHERE Contract_No=a.FO_NO AND Role='User' AND DateIn>=@StartTime AND DateIn<@EndTime) AS UserTotalScore FROM FC_SESRelatedData AS a INNER JOIN FC_SESReport AS b ON a.FO_NO=b.FO LEFT JOIN Score_JournalEvaluation AS c ON b.SES_No=c.SES_No LEFT JOIN Base_Contractor AS d ON d.ContractorId=a.Contractor LEFT JOIN dbo.Sys_User AS u ON u.UserId = a.Main_Coordinator LEFT JOIN Base_Discipline AS dis ON dis.DisciplineId = a.DisciplineId WHERE ISNULL(b.Requisitioner,'')!='' AND a.DisciplineId<>'ddcd51c2-1059-4cc8-8f6f-8936da88a4c4' AND (ISNULL(b.Claim_sheets_receive,'')!='' OR ISNULL(b.TECO_Date,'')!='') AND ISNULL(b.Deleted,'')='' AND ISNULL(b.Blocked,'')='' AND c.Evaluate_Time>=@StartTime AND c.Evaluate_Time<@EndTime GROUP BY a.FO_NO,a.FOTypeId,b.FO,dis.Discipline,dis.DisciplineCN,d.Contractor,d.ContractorCN,u.UserName,a.Main_Coordinator,a.User_Representative,a.Contract_Admin ) AS tab --WHERE tab.Work_Description NOT LIKE '%特殊作业安全监护%' END GO ALTER PROCEDURE [dbo].[FN_Safety_OverviewReport] @StartTime DATETIME, @EndTime DATETIME AS BEGIN SELECT tab.FO_NO,tab.Work_Description,tab.Contractor,tab.Main_Coordinator,tab.UserNum,tab.EvaluateNum, --部门已评人数Score1 tab.DepYpScore1,tab.DepZpScore1, --部门已评人数Score2 tab.DepYpScore2,tab.DepZpScore2, --部门已评人数Score3 tab.DepYpScore3,tab.DepZpScore3, --部门已评人数Score4 tab.DepYpScore4,tab.DepZpScore4, --部门已评人数Score5 tab.DepYpScore5,tab.DepZpScore5, --部门已评人数Score6 tab.DepYpScore6,tab.DepZpScore6, --用户占35%,部门占60% CONVERT(DECIMAL(9,1),((CASE WHEN tab.EvaluateNum>0 THEN (ISNULL(tab.AvgEvaScore1,0)+ ISNULL(tab.AvgEvaScore2,0)+ ISNULL(tab.AvgEvaScore3,0)+ --ISNULL(tab.AvgEvaScore4,0)+ ISNULL(tab.AvgEvaScore5,0)+ ISNULL(tab.AvgEvaScore6,0))*35/35 ELSE 0 END)+ (CASE WHEN ((CASE WHEN tab.CTSSAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTSCAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.MainCoordinatorAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.UserRepresentativeAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.CTSTAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTEDAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.TimelyAvgSocre IS NOT NULL THEN 5 ELSE 0 END)+ (CASE WHEN tab.HonestyAvgScore IS NOT NULL THEN 5 ELSE 0 END))>0 THEN ((ISNULL(tab.CTSSAvgScore,0)+ ISNULL(tab.CTSCAvgScore,0)+ISNULL(tab.MainCoordinatorAvgScore,0)+ ISNULL(tab.UserRepresentativeAvgScore,0)+ISNULL(tab.CTSTAvgScore,0)+ISNULL(tab.CTEDAvgScore,0)+ ISNULL(tab.TimelyAvgSocre,0)+ISNULL(tab.HonestyAvgScore,0))*65) / ((CASE WHEN tab.CTSSAvgScore>=0 THEN 15 ELSE 0 END)+(CASE WHEN tab.CTSCAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.MainCoordinatorAvgScore>=0 THEN 10 ELSE 0 END)+(CASE WHEN tab.UserRepresentativeAvgScore>=0 THEN 15 ELSE 0 END)+ (CASE WHEN tab.CTSTAvgScore>=0 THEN 5 ELSE 0 END)+(CASE WHEN tab.CTEDAvgScore>=0 THEN 5 ELSE 0 END)+ (CASE WHEN tab.TimelyAvgSocre IS NOT NULL THEN 5 ELSE 0 END)+ (CASE WHEN tab.HonestyAvgScore IS NOT NULL THEN 5 ELSE 0 END)) ELSE 0 END) )) AS Total, (CASE WHEN (CONVERT(DECIMAL(18,2),(tab.EvaluateNum*5)+DepYpScore1+DepYpScore2+DepYpScore3+DepYpScore4+DepYpScore5+DepYpScore6)/ CONVERT(DECIMAL(18,2),(tab.UserNum*5)+DepZpScore1+DepZpScore2+DepZpScore3+DepZpScore4+DepZpScore5+DepZpScore6 ))>1 THEN 100.00 ELSE CONVERT(DECIMAL(18,2),(CONVERT(DECIMAL(18,2),(tab.EvaluateNum*5)+DepYpScore1+DepYpScore2+DepYpScore3+DepYpScore4+DepYpScore5+DepYpScore6)/ CONVERT(DECIMAL(18,2),(tab.UserNum*5)+DepZpScore1+DepZpScore2+DepZpScore3+DepZpScore4+DepZpScore5+DepZpScore6 ))*100) END) AS Participation_Rate,--参与率 tab.AvgEvaScore1,--评价均分(工作准备) tab.TotalAvgScore1,--总平均分 tab.AvgEvaScore2, tab.TotalAvgScore2, tab.AvgEvaScore3, tab.TotalAvgScore3, --tab.AvgEvaScore4, --tab.TotalAvgScore4, tab.AvgEvaScore5, tab.TotalAvgScore5, tab.AvgEvaScore6, tab.TotalAvgScore6, tab.TimelyAvgSocre, tab.HonestyAvgScore, tab.CTSSAvgScore, tab.CTSCAvgScore, tab.MainCoordinatorAvgScore, tab.UserRepresentativeAvgScore, tab.CTSTAvgScore, tab.CTEDAvgScore, FORMAT(DATEADD(MONTH,-1,@StartTime),'yyyy-MM') AS ReportMonth FROM (SELECT a.FO_NO,(ISNULL(dis.Discipline,'')+ISNULL(dis.DisciplineCN,'')) AS Work_Description,(d.Contractor+d.ContractorCN)AS Contractor,u.UserName AS Main_Coordinator, --总评价数 COUNT(DISTINCT(Requisitioner)) AS UserNum, --用户已评人数 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='User' AND ISNULL(Remark,'')!='Auto') AS EvaluateNum, --部门已评人数score1 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score1>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore1, --部门总评人数score1 CTS/S (SELECT COUNT(1) FROM Sys_User WHERE RoleId='39e35a17-8fa2-447c-b1da-bf92bff36ad4') AS DepZpScore1, --部门已评人数score2 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score2>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore2, --部门总评人数score2 CTS/C (SELECT COUNT(1) FROM Sys_User WHERE RoleId='b76dec7a-ba1c-46f1-8859-ece4b18252b1') AS DepZpScore2, --部门已评人数score3 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score3>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore3, --部门总评人数score3 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.Main_Coordinator) AS DepZpScore3, --部门已评人数score4 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score4>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore4, --部门总评人数score4 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.User_Representative) AS DepZpScore4, --部门已评人数score5 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score5>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore5, --部门总评人数score5 CTM/T (SELECT COUNT(1) FROM Sys_User WHERE RoleId='111eb3c5-a3b7-49de-a40b-e5bb3fd10944') AS DepZpScore5, --部门已评人数score6 (SELECT COUNT(DISTINCT(UserName)) FROM FC_Score WHERE ISNULL(UserName,'')!='' AND DateIn>=@StartTime AND DateIn<@EndTime AND Contract_No=b.FO AND [Role]='Dep' AND Score6>=0 AND ISNULL(Remark,'')!='Auto') AS DepYpScore6, --部门总评人数score6 (SELECT COUNT(DISTINCT(ma.Account)) FROM Sys_User AS ma WHERE ma.UserId=a.Contract_Admin) AS DepZpScore6, --工作准备Preparation 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score1>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore1, --工作准备Preparation 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore1, --工作表现Performance 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score2>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore2, --工作表现Performance 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore2, --EHSS管理 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score3>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore3, --EHSS管理 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore3, --质量控制Quality Control 评价均分 --(SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score4>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore4, --质量控制Quality Control 总平均分 --(SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore4, --时间管理Timeline Management 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score5>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore5, --时间管理Timeline Management 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore5, --文档管理Documentation 评价均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.DateIn>=@StartTime AND f.DateIn<@EndTime AND Contract_No=a.FO_NO AND f.Score6>=0 AND f.[Role]='User' AND ISNULL(f.Remark,'')!='Auto') AS AvgEvaScore6, --文档管理Documentation 总平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='User' AND f.DateIn>=@StartTime AND f.DateIn<@EndTime) AS TotalAvgScore6, --"及时性Timely submission"平均分 (CASE WHEN a.FOTypeId='e3dd9ecc-4474-4e94-85ff-22dc073fd8b0' THEN --FC (SELECT CONVERT(DECIMAL(18,2),AVG(f.Timely)) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) WHEN a.FOTypeId='eb846026-639f-4063-8d3d-a253905ddfe0' THEN --TAR (SELECT CONVERT(DECIMAL(18,2),AVG(f.Timely)) FROM dbo.TAR_HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) WHEN a.FOTypeId='58544360-5d26-4358-8459-928aa5f6e3ab' AND (SELECT COUNT(*) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime)>0 THEN --OEM CONVERT(DECIMAL(18,2),5.0) END) AS TimelyAvgSocre, --"诚实度Honesty"平均分 (SELECT CONVERT(DECIMAL(18,2),AVG(f.Honesty)) FROM HonestyTimelyView AS f WHERE f.Contract_No=a.FO_NO AND f.DateIn>=DATEADD(MONTH,-1,@EndTime) AND f.DateIn<@EndTime) AS HonestyAvgScore, --CTS/S (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score1)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score1>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSSAvgScore, --CTS/C (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score2)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score2>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSCAvgScore, --Main Coordinator (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score3)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score3>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS MainCoordinatorAvgScore, --User Representative (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score4)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score4>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS UserRepresentativeAvgScore, --CTM/T (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score5)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score5>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTSTAvgScore, --CTE/D (SELECT CONVERT(DECIMAL(18,2),AVG(f.Score6)) FROM FC_Score AS f WHERE f.Contract_No=a.FO_NO AND f.[Role]='Dep' AND f.Score6>=0 AND f.DateIn>=@StartTime AND f.DateIn<@EndTime AND ISNULL(f.Remark,'')!='Auto') AS CTEDAvgScore --用户总分 --(SELECT ISNULL(CONVERT(DECIMAL(18,2),AVG(f.Score1+f.Score2+f.Score3+f.Score4+f.Score5+f.Score6+f.Score7)),0.00)FROM FC_Score AS f WHERE Contract_No=a.FO_NO AND Role='User' AND DateIn>=@StartTime AND DateIn<@EndTime) AS UserTotalScore FROM FC_SESRelatedData AS a INNER JOIN FC_SESReport AS b ON a.FO_NO=b.FO LEFT JOIN Score_JournalEvaluation AS c ON b.SES_No=c.SES_No LEFT JOIN Base_Contractor AS d ON d.ContractorId=a.Contractor LEFT JOIN dbo.Sys_User AS u ON u.UserId = a.Main_Coordinator LEFT JOIN Base_Discipline AS dis ON dis.DisciplineId = a.DisciplineId WHERE ISNULL(b.Requisitioner,'')!='' AND a.DisciplineId='ddcd51c2-1059-4cc8-8f6f-8936da88a4c4' AND (ISNULL(b.Claim_sheets_receive,'')!='' OR ISNULL(b.TECO_Date,'')!='') AND ISNULL(b.Deleted,'')='' AND ISNULL(b.Blocked,'')='' AND c.Evaluate_Time>=@StartTime AND c.Evaluate_Time<@EndTime GROUP BY a.FO_NO,a.FOTypeId,b.FO,dis.Discipline,dis.DisciplineCN,d.Contractor,d.ContractorCN,u.UserName,a.Main_Coordinator,a.User_Representative,a.Contract_Admin ) AS tab --WHERE tab.Work_Description LIKE '%特殊作业安全监护%' END GO CREATE TABLE [dbo].[FC_OverviewReport]( [Id] [INT] IDENTITY(1,1) NOT NULL, [ReportMonth] [NVARCHAR](50) NULL, [FO_NO] [NVARCHAR](50) NULL, [Work_Description] [NVARCHAR](300) NULL, [Contractor] [NVARCHAR](300) NULL, [Main_Coordinator] [NVARCHAR](50) NULL, [Total] [DECIMAL](9, 1) NULL, [Participation_Rate] [DECIMAL](18, 2) NULL, [EvaluateNum] [INT] NULL, [UserNum] [INT] NULL, [AvgEvaScore1] [DECIMAL](18, 2) NULL, [TotalAvgScore1] [DECIMAL](18, 2) NULL, [AvgEvaScore2] [DECIMAL](18, 2) NULL, [TotalAvgScore2] [DECIMAL](18, 2) NULL, [AvgEvaScore3] [DECIMAL](18, 2) NULL, [TotalAvgScore3] [DECIMAL](18, 2) NULL, [AvgEvaScore4] [DECIMAL](18, 2) NULL, [TotalAvgScore4] [DECIMAL](18, 2) NULL, [AvgEvaScore5] [DECIMAL](18, 2) NULL, [TotalAvgScore5] [DECIMAL](18, 2) NULL, [AvgEvaScore6] [DECIMAL](18, 2) NULL, [TotalAvgScore6] [DECIMAL](18, 2) NULL, [TimelyAvgSocre] [DECIMAL](18, 2) NULL, [HonestyAvgScore] [DECIMAL](18, 2) NULL, [CTSSAvgScore] [DECIMAL](18, 2) NULL, [CTSCAvgScore] [DECIMAL](18, 2) NULL, [MainCoordinatorAvgScore] [DECIMAL](18, 2) NULL, [UserRepresentativeAvgScore] [DECIMAL](18, 2) NULL, [CTSTAvgScore] [DECIMAL](18, 2) NULL, [CTEDAvgScore] [DECIMAL](18, 2) NULL, [IsSafe] [BIT] NULL, CONSTRAINT [PK_FC_OverviewReport] PRIMARY KEY CLUSTERED ( [Id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] GO ALTER PROCEDURE [dbo].[FN_NoEvaluationUsersReport] @StartTime datetime, @EndTime datetime AS BEGIN SELECT NEWID() as FoGuid, a.Contract_No, a.UserName as Evaluate_UserName, s.UserName, 'No' as isEvaluate, a.[Role] as RoleName, c.DepartName, FORMAT(DATEADD(MONTH,-1,@StartTime),'yyyy-MM') AS ReportMonth, (CASE WHEN a.Score1>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTS/S')) ELSE '' END) AS CTSSEva, (CASE WHEN a.Score2>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTS/C')) ELSE '' END) AS CTSCEva, (CASE WHEN a.Score3>0 THEN (SELECT TOP 1 Main_Coordinator FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS MainCEva, (CASE WHEN a.Score4>0 THEN (SELECT TOP 1 User_Representative FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS UserREva, (CASE WHEN a.Score5>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTM/T') ORDER BY UserId) ELSE '' END) AS CTMT1Eva, (CASE WHEN a.Score5>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTM/T') ORDER BY UserId DESC) ELSE '' END) AS CTMT2Eva, (CASE WHEN a.Score6>0 THEN (SELECT TOP 1 Contract_Admin FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS ConAREva FROM FC_Score as a LEFT join Sys_User as s on s.Account=a.UserName LEFT join Base_Depart as c on c.DepartId=s.DepartId LEFT join dbo.FC_SESRelatedData as fc on a.Contract_No=fc.FO_NO where a.DateIn>=@StartTime AND a.DateIn<@EndTime AND fc.DisciplineId<>'ddcd51c2-1059-4cc8-8f6f-8936da88a4c4' --AND dis.DisciplineCN NOT LIKE '%特殊作业安全监护%' AND a.Remark='Auto' ORDER BY a.Role DESC END GO ALTER PROCEDURE [dbo].[FN_Safety_NoEvaluationUsersReport] @StartTime datetime, @EndTime datetime AS BEGIN SELECT NEWID() as FoGuid, a.Contract_No, a.UserName as Evaluate_UserName, s.UserName, 'No' as isEvaluate, a.[Role] as RoleName, c.DepartName, FORMAT(DATEADD(MONTH,-1,@StartTime),'yyyy-MM') AS ReportMonth, (CASE WHEN a.Score1>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTS/S')) ELSE '' END) AS CTSSEva, (CASE WHEN a.Score2>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTS/C')) ELSE '' END) AS CTSCEva, (CASE WHEN a.Score3>0 THEN (SELECT TOP 1 Main_Coordinator FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS MainCEva, (CASE WHEN a.Score4>0 THEN (SELECT TOP 1 User_Representative FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS UserREva, (CASE WHEN a.Score5>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTM/T') ORDER BY UserId) ELSE '' END) AS CTMT1Eva, (CASE WHEN a.Score5>0 THEN (SELECT TOP 1 UserId FROM dbo.Sys_User WHERE RoleId=(SELECT TOP 1 RoleId FROM dbo.Sys_Role WHERE RoleName='CTM/T') ORDER BY UserId DESC) ELSE '' END) AS CTMT2Eva, (CASE WHEN a.Score6>0 THEN (SELECT TOP 1 Contract_Admin FROM dbo.FC_SESRelatedData WHERE FO_NO=a.Contract_No) ELSE '' END) AS ConAREva FROM FC_Score as a LEFT join Sys_User as s on s.Account=a.UserName LEFT join Base_Depart as c on c.DepartId=s.DepartId LEFT join dbo.FC_SESRelatedData as fc on a.Contract_No=fc.FO_NO where a.DateIn>=@StartTime AND a.DateIn<@EndTime AND fc.DisciplineId='ddcd51c2-1059-4cc8-8f6f-8936da88a4c4' --AND dis.DisciplineCN LIKE '%特殊作业安全监护%' AND a.Remark='Auto' ORDER BY a.Role DESC END GO CREATE TABLE [dbo].[FC_NoEvaluatedUser]( [Id] [INT] IDENTITY(1,1) NOT NULL, [ReportMonth] [NVARCHAR](50) NULL, [NotEvaluatedFoNo] [NVARCHAR](2000) NULL, [Account] [NVARCHAR](50) NULL, [UserName] [NVARCHAR](50) NULL, [isEvaluate] [NVARCHAR](10) NULL, [RoleName] [NVARCHAR](50) NULL, [DepartName] [NVARCHAR](50) NULL, [IsSafe] [BIT] NULL, CONSTRAINT [PK_FC_NoEvaluatedUser] PRIMARY KEY CLUSTERED ( [Id] ASC )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] ) ON [PRIMARY] GO ALTER VIEW [dbo].[View_FC_SESRelatedData] AS /*********合同视图**********/ SELECT datas.ID, datas.FO_NO, datas.FOTypeId, ft.FOType, datas.Pricing_Scheme AS Pricing_SchemeId, ps.PriceScheme AS Pricing_Scheme, datas.Contractor AS ContractorId, con.Contractor AS Contractor_Eng, con.ContractorCN AS Contraor_CN, (CASE WHEN con.Contractor IS NULL THEN con.ContractorCN WHEN con.ContractorCN IS NULL THEN con.Contractor ELSE con.Contractor+con.ContractorCN END)AS Contractor, datas.Vendor_NO, item.Item, datas.DisciplineId, dis.Discipline AS Discipline_Eng, dis.DisciplineCN AS Discipline_CN, (CASE WHEN dis.Discipline IS NULL THEN dis.DisciplineCN WHEN dis.DisciplineCN IS NULL THEN dis.Discipline ELSE dis.Discipline+dis.DisciplineCN END) AS Discipline, datas.Original_WC AS DisciplineCategory, cur.Currency, datas.Material_Group, datas.Purchase_Group, datas.Cost_Element, t.[Type], datas.Contract_Admin AS Contract_AdminId, u.UserName AS Contract_Admin, u.ChineseName AS ChineseName, ch.UserName AS Cost_Checker, datas.Buyer, datas.Main_Coordinator AS Main_CoordinatorId, u2.UserName AS Main_Coordinator, --datas.Applicant AS MCDept, dep.DepartCode AS MCDept, u3.UserName AS User_Representative, datas.User_Representative AS User_RepresentativeId, datas.Validate_Date, datas.Expire_Date, datas.FC_Status, datas.Contract_Person, datas.Contract_Tel, datas.Allocation, (CASE WHEN datas.Proportion_of_FC_Definition IS NOT NULL THEN CONVERT(VARCHAR(10),CONVERT(DECIMAL(9,2),datas.Proportion_of_FC_Definition*100.0))+'%' END) AS StrVolumeAllocation, datas.Proportion_of_FC_Definition AS VolumeAllocation, datas.Actual_Budget, datas.Connectedtransaction, CONVERT(DECIMAL(18,2),ISNULL(c.CheckedValue,0)) AS CheckedValue, CONVERT(DECIMAL(18,2),(ISNULL(datas.Actual_Budget,0)-ISNULL(c.CheckedValue,0))) AS RemainingBudget, CONVERT(VARCHAR(10),CONVERT(DECIMAL(18,2),(datas.Actual_Budget-ISNULL(c.CheckedValue,0))/datas.Actual_Budget*100))+'%' AS RemainingBudgetRate,--值=Remaining Budget/Contract Budget (CASE WHEN DATEDIFF(DAY,datas.Validate_Date,datas.Expire_Date)>0 THEN CONVERT(VARCHAR(10),CONVERT(DECIMAL(18,2),CONVERT(DECIMAL(18,2),DATEDIFF(DAY,GETDATE(),datas.Expire_Date))/CONVERT(DECIMAL(18,2),DATEDIFF(DAY,datas.Validate_Date,datas.Expire_Date))*100))+'%' ELSE ''END) AS RemainingDuration, --公式:值=合同过期日-今天 / 合同生效总天数 datas.Email, datas.MainHead, datas.MainHeadContact, datas.SafetyOfficer, datas.SafetyOfficerContact, datas.ProjectManager, datas.ProjectManagerContact, datas.ConstRecords, datas.ExceedLimit, datas.Remark FROM FC_SESRelatedData AS datas LEFT JOIN dbo.Base_Contractor AS con ON con.ContractorId = datas.Contractor LEFT JOIN dbo.Base_PriceScheme AS ps ON ps.PriceSchemeId = datas.Pricing_Scheme LEFT JOIN dbo.Base_Item AS item ON item.ItemId = datas.Item LEFT JOIN dbo.Base_Currency AS cur ON cur.CurrencyId = datas.Currency LEFT JOIN dbo.Base_Type AS t ON t.TypeId = datas.Type LEFT JOIN dbo.Sys_User AS u ON u.UserId = datas.Contract_Admin LEFT JOIN dbo.Sys_User AS ch ON ch.UserId = datas.Cost_Checker LEFT JOIN dbo.Sys_User AS u2 ON u2.UserId = datas.Main_Coordinator LEFT JOIN dbo.Sys_User AS u3 ON u3.UserId=datas.User_Representative LEFT JOIN dbo.Base_Depart dep ON dep.DepartId=u2.DepartId LEFT JOIN dbo.Base_Discipline AS dis ON dis.DisciplineId = datas.DisciplineId LEFT JOIN dbo.Base_FOType AS ft ON ft.FOTypeId = datas.FOTypeId --LEFT JOIN(SELECT SUM(Net_Value) AS CheckedValue,CPTList.Contract_No FROM dbo.SESList -- LEFT JOIN dbo.CPTList ON CPTList.CPT_No = SESList.CPT_No GROUP BY CPTList.Contract_No) AS c ON c.Contract_No=datas.FO_NO LEFT JOIN(SELECT SUM(ISNULL(SSR_Actual_cost,0)) AS CheckedValue,FO FROM dbo.FC_SESReport WHERE Accepted='X' GROUP BY FO) AS c ON c.FO=datas.FO_NO GO ALTER VIEW [dbo].[View_FC_Report] AS /*********ºÏͬÊÓͼ**********/ SELECT t.ID,t.FO_NO, t.Contractor,t.DisciplineId,t.Discipline,t.Contract_Admin,t.Buyer,t.Main_Coordinator, t.ContractorId,t.MCDept,t.FC_Status,t.ConstRecords,t.Contract_AdminId,t.Main_CoordinatorId, t.Budget,t.Actual_Cost,t.Commitment, t.Spending_commitment, t.Validate_Date,t.Expire_Date, t.UnusedBudget,t.UnusedBudgetRate,t.Volume_Allocation, CONVERT(VARCHAR(10),CONVERT(DECIMAL(18,2),t.Target_Volume*100))+'%' AS Target_Volume, (CASE WHEN t.Volume_Allocation='N' THEN NULL ELSE CONVERT(VARCHAR(10),CAST( (CASE WHEN t.Sum_Spending_commitment>0 THEN 100.0*t.Spending_commitment1/t.Sum_Spending_commitment ELSE CONVERT(VARCHAR(10),CONVERT(DECIMAL(18,2),t.Target_Volume*100)) END) AS DECIMAL(18,2)))+'%' END) AS Actual_Volume, (CASE WHEN t.Volume_Allocation='N' THEN NULL ELSE CONVERT(VARCHAR(10),CAST((CASE WHEN t.Sum_Spending_commitment>0 THEN 1.0*t.Spending_commitment1/t.Sum_Spending_commitment ELSE 0 END-t.Target_Volume)*100 AS DECIMAL(18,2)))+'%' END) AS Volume_Deviation, (CASE WHEN t.Volume_Allocation='N' THEN NULL ELSE CASE WHEN((CASE WHEN t.Sum_Spending_commitment>0 THEN 1.0*t.Spending_commitment1/t.Sum_Spending_commitment ELSE 0 END)-t.Target_Volume)>0.1 OR (t.Target_Volume-(CASE WHEN t.Sum_Spending_commitment>0 THEN 1.0*t.Spending_commitment1/t.Sum_Spending_commitment ELSE 0 END))>0.1 THEN 'Y' ELSE 'OK' END END) AS Volume_allocation_deviation, (CASE WHEN t.Sum_Spending_commitment=0 THEN 'OK' ELSE (CASE WHEN t.UnusedBudget<0.1 THEN 'Y' ELSE 'OK' END) END) AS Budget_Running_out, (CASE WHEN t.Budget_progress=0 THEN 'OK' ELSE CASE WHEN ((t.Spending_commitment-t.Budget_progress)/t.Budget_progress)>0.5 THEN 'Y' ELSE 'OK' END END) AS Budget_progress_VS_Time FROM (SELECT datas.ID, datas.FO_NO, datas.DisciplineId,datas.Contractor AS ContractorId, datas.Contract_Admin AS Contract_AdminId,datas.Main_Coordinator AS Main_CoordinatorId, (CASE WHEN con.Contractor IS NULL THEN con.ContractorCN WHEN con.ContractorCN IS NULL THEN con.Contractor ELSE con.Contractor+con.ContractorCN END)AS Contractor, (CASE WHEN dis.Discipline IS NULL THEN dis.DisciplineCN WHEN dis.DisciplineCN IS NULL THEN dis.Discipline ELSE dis.Discipline+dis.DisciplineCN END) AS Discipline, u.UserName AS Contract_Admin, datas.Buyer, u2.UserName AS Main_Coordinator, dep.DepartCode AS MCDept,--datas.Applicant AS MCDept, datas.FC_Status, datas.ConstRecords,datas.Actual_Budget AS Budget, CONVERT(DECIMAL(18,2),ISNULL(c.CheckedValue,0)) AS Actual_Cost, CONVERT(DECIMAL(18,2),ISNULL(a.Commitment,0)) AS Commitment, (CASE WHEN datas.FO_NO='4970925603' THEN (CONVERT(DECIMAL(18,2),ISNULL(c.CheckedValue,0))+CONVERT(DECIMAL(18,2),ISNULL(a.Commitment,0)) -(SELECT TOP 1 CONVERT(DECIMAL(18,2),ISNULL(s.Offset,0)) FROM dbo.Base_FOOffset s WHERE s.FO_NO=datas.FO_NO)) ELSE (CONVERT(DECIMAL(18,2),ISNULL(c.CheckedValue,0))+CONVERT(DECIMAL(18,2),ISNULL(a.Commitment,0))) END) AS Spending_commitment1, (CONVERT(DECIMAL(18,2),ISNULL(c.CheckedValue,0))+CONVERT(DECIMAL(18,2),ISNULL(a.Commitment,0))) AS Spending_commitment, (CASE WHEN datas.FO_NO='4970925603' OR datas.FO_NO='4974804732' THEN (SELECT SUM(ISNULL(Spending_commitment,0)) FROM View_Sum_Spending_Commitment t WHERE t.DisciplineId= datas.DisciplineId)-(SELECT TOP 1 CONVERT(DECIMAL(18,2),ISNULL(s.Offset,0)) FROM dbo.Base_FOOffset s WHERE s.FO_NO=datas.FO_NO) ELSE (SELECT SUM(ISNULL(Spending_commitment,0)) FROM View_Sum_Spending_Commitment t WHERE t.DisciplineId= datas.DisciplineId ) END) AS Sum_Spending_commitment, datas.Validate_Date, datas.Expire_Date, CONVERT(DECIMAL(18,2),(ISNULL(datas.Actual_Budget,0)-ISNULL(c.CheckedValue,0)-ISNULL(a.Commitment,0))) AS UnusedBudget, CONVERT(VARCHAR(10),CONVERT(DECIMAL(18,2),(datas.Actual_Budget-ISNULL(c.CheckedValue,0)-ISNULL(a.Commitment,0))*100/datas.Actual_Budget))+'%' AS UnusedBudgetRate,--Öµ=Remaining Budget/Contract Budget (CASE WHEN datas.Proportion_of_FC_Definition=1 THEN 'N' ELSE 'Y' END) AS Volume_Allocation, datas.Proportion_of_FC_Definition AS Target_Volume, (CASE WHEN DATEDIFF(DAY,datas.Validate_Date,datas.Expire_Date)>0 THEN CONVERT(DECIMAL(18,2),(datas.Actual_Budget*DATEDIFF(DAY,datas.Validate_Date,GETDATE()))/DATEDIFF(DAY,datas.Validate_Date,datas.Expire_Date)) ELSE 0 END) AS Budget_progress FROM FC_SESRelatedData AS datas LEFT JOIN dbo.Base_Contractor AS con ON con.ContractorId = datas.Contractor LEFT JOIN dbo.Sys_User AS u ON u.UserId = datas.Contract_Admin LEFT JOIN dbo.Sys_User AS u2 ON u2.UserId = datas.Main_Coordinator LEFT JOIN dbo.Base_Depart dep ON dep.DepartId=u2.DepartId LEFT JOIN dbo.Base_Discipline AS dis ON dis.DisciplineId = datas.DisciplineId LEFT JOIN dbo.Base_FOType AS ft ON ft.FOTypeId = datas.FOTypeId LEFT JOIN(SELECT SUM(ISNULL(SSR_Actual_cost,0)) AS CheckedValue,FO FROM dbo.FC_SESReport WHERE Accepted='X' AND Deleted <> 'X' AND Blocked <> 'X' GROUP BY FO) AS c ON c.FO=datas.FO_NO LEFT JOIN(SELECT SUM(ISNULL(SSR_budget,0)) AS Commitment,FO FROM dbo.FC_SESReport WHERE Accepted <> 'X' AND Deleted <> 'X' AND Blocked <> 'X' GROUP BY FO) AS a ON a.FO=datas.FO_NO WHERE ft.FOType!='OEM' AND dis.Discipline NOT LIKE '%Basf Expert Service%' AND datas.Expire_Date<>'2099-01-01' AND datas.FC_Status!='Closed' AND (datas.Expire_Date IS NOT NULL AND DATEDIFF(MONTH,datas.Expire_Date,GETDATE())<=1) --Ò»¸öÔ ) t GO