GO /****** Object: StoredProcedure [dbo].[spInOutManHoursReport] Script Date: 2025-12-25 18:14:07 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO ALTER PROC [dbo].[spInOutManHoursReport] @projectId NVARCHAR(50), @unitId NVARCHAR(max)= NULL, @postId NVARCHAR(max)= NULL, @startTime DATETIME = NULL, @endTime DATETIME = NULL AS /*****************单位考勤****************/ SET NOCOUNT ON; -- 1. 创建临时表存储过滤的单位ID CREATE TABLE #FilteredUnits (UnitId NVARCHAR(50) PRIMARY KEY); IF @unitId IS NOT NULL AND LTRIM(RTRIM(@unitId)) <> '' BEGIN INSERT INTO #FilteredUnits (UnitId) select distinct items from split(@unitId,',') END -- 2. 创建临时表存储过滤的岗位ID CREATE TABLE #FilteredPosts (WorkPostId NVARCHAR(50) PRIMARY KEY); IF @postId IS NOT NULL AND LTRIM(RTRIM(@postId)) <> '' BEGIN INSERT INTO #FilteredPosts (WorkPostId) select distinct items from split(@postId,',') END ; -- 3. 使用CTE预先聚合人员统计数据(避免相关子查询) WITH InOutRecord AS ( SELECT T.ProjectId,P.UnitId,P.WorkPostId as PostId,ManHours ,ISNULL((case when P.UnitId=''then null else (case when u.ShortUnitName IS NOT NULL THEN u.ShortUnitName ELSE u.UnitName END) end),'未知') AS UnitName ,ISNULL((case when P.UnitId=''then null else u.UnitName end),'未知') AS AllUnitName ,ISNULL((case when W.WorkPostName=''then null else W.WorkPostName end),'未知') AS PostName ,T.NewID,U.ShortUnitName FROM dbo.t_d_EmployInOutRecord AS T WITH(NOLOCK) LEFT JOIN dbo.SitePerson_Person AS P WITH(NOLOCK) ON T.ProjectId=P.ProjectId AND T.IDCardNo=P.IdentityCard LEFT JOIN dbo.Base_Unit AS U WITH(NOLOCK) ON P.UnitId=U.UnitId LEFT JOIN dbo.Base_WorkPost AS W WITH(NOLOCK) ON P.WorkPostId=W.WorkPostId WHERE 1=1 AND T.ProjectId = @ProjectId AND (@startTime IS NULL OR T.RecordDate >= @startTime) AND (@endTime IS NULL OR T.RecordDate <= @endTime) AND (@unitId IS NULL OR EXISTS (SELECT 1 FROM #FilteredUnits WHERE UnitId = P.UnitId)) AND (@postId IS NULL OR EXISTS (SELECT 1 FROM #FilteredPosts WHERE WorkPostId = P.WorkPostId)) ), PerCountSum AS ( SELECT COUNT(PersonId) AS PersonCountSum,ProjectId,UnitId,WorkPostId FROM dbo.SitePerson_Person AS SP WITH(NOLOCK) WHERE IsUsed=1 AND OutTime IS NOT NULL AND ProjectId = @ProjectId AND (@unitId IS NULL OR EXISTS (SELECT 1 FROM #FilteredUnits WHERE UnitId = SP.UnitId)) AND (@postId IS NULL OR EXISTS (SELECT 1 FROM #FilteredPosts WHERE WorkPostId = SP.WorkPostId)) GROUP BY ProjectId,UnitId,WorkPostId ) -- 4. 主查询 - 优化后的JOIN结构 SELECT CAST(NEWID() AS NVARCHAR(100)) AS ID,InOutRecord.ProjectId,InOutRecord.UnitId,InOutRecord.UnitName,InOutRecord.AllUnitName,InOutRecord.PostName ,SUM(ISNULL(InOutRecord.ManHours, 0)) AS ManHoursSum ,COUNT(InOutRecord.NewID) AS ManCountSum ,PerCountSum.PersonCountSum FROM InOutRecord LEFT JOIN PerCountSum ON PerCountSum.UnitId=InOutRecord.UnitId AND PerCountSum.WorkPostId=InOutRecord.PostId AND PerCountSum.ProjectId=InOutRecord.ProjectId GROUP BY InOutRecord.ProjectId,InOutRecord.UnitId,InOutRecord.UnitName,InOutRecord.AllUnitName,InOutRecord.PostId,InOutRecord.PostName,PerCountSum.PersonCountSum ORDER BY ISNULL(InOutRecord.UnitName, InOutRecord.AllUnitName),InOutRecord.PostName -- 清理临时表 DROP TABLE #FilteredUnits; DROP TABLE #FilteredPosts; --2025-12-25修改之前 xiaj --SELECT CAST(NEWID() AS NVARCHAR(100)) AS ID -- ,T.ProjectId -- ,p.UnitId -- ,ISNULL((case when P.UnitId=''then null -- else (case when u.ShortUnitName IS NOT NULL THEN u.ShortUnitName ELSE u.UnitName END) end),'未知') AS UnitName -- ,ISNULL((case when P.UnitId=''then null -- else u.UnitName end),'未知') AS AllUnitName -- ,p.WorkPostId as PostId -- ,ISNULL((case when W.WorkPostName=''then null else W.WorkPostName end),'未知') AS PostName -- ,SUM(ISNULL(ManHours,0)) AS ManHoursSum -- ,COUNT(T.NewID) AS ManCountSum -- ,(SELECT COUNT(PersonId) FROM SitePerson_Person -- WHERE ProjectId = T.ProjectId AND P.UnitId=UnitId AND P.WorkPostId=WorkPostId AND IsUsed=1 AND OutTime IS NOT NULL -- group by ProjectId,UnitId,WorkPostId) AS PersonCountSum --FROM dbo.t_d_EmployInOutRecord AS T --LEFT JOIN dbo.SitePerson_Person AS P ON T.ProjectId=P.ProjectId AND T.IDCardNo=P.IdentityCard --LEFT JOIN dbo.Base_Unit AS U ON P.UnitId=U.UnitId ----LEFT JOIN dbo.ProjectData_TeamGroup AS Team ON P.TeamGroupId=Team.TeamGroupId --LEFT JOIN dbo.Base_WorkPost AS W ON P.WorkPostId=W.WorkPostId --WHERE T.ProjectId = @ProjectId --AND (RecordDate >= @startTime OR @startTime IS NULL) --AND (RecordDate <= @endTime OR @endTime IS NULL) --AND (@unitId like '%'+P.UnitId+'%' OR @unitId IS NULL) --AND (@postId like '%'+P.WorkPostId+'%' OR @postId IS NULL) --GROUP BY T.ProjectId,P.UnitId,U.UnitName,u.ShortUnitName,P.WorkPostId,W.WorkPostName GO