USE [DriveMaintenance] GO /****** Object: StoredProcedure [dbo].[Proc_AnnualEquipmentMaintenanceProgram] Script Date: 2024/7/29 13:42:15 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= ALTER PROCEDURE [dbo].[Proc_AnnualEquipmentMaintenanceProgram] @Year INT = 0, @Keyword NVARCHAR(50) = '' AS BEGIN IF @Year = 0 BEGIN SET @Year = YEAR(GETDATE()); END; DECLARE @defaultLanguage NVARCHAR(50); SELECT @defaultLanguage = lan.name FROM sys.configurations config INNER JOIN sys.syslanguages lan ON config.value = lan.langid WHERE config.name LIKE 'default language%'; SET LANGUAGE 'us_english'; WITH plans AS (SELECT AutoID, GUID, EquipmentID, CompleteDate, MaintenanceYear, MaintenanceMonth, SUBSTRING(DATENAME(MONTH, CONCAT(MaintenanceYear, '-', MaintenanceMonth, '-', 1)), 1, 3) AS MaintenanceMonthName, SUBSTRING(DATENAME(MONTH, CONCAT(MaintenanceYear, '-', MaintenanceMonth, '-', 1)), 1, 3) + 'Status' AS MaintenanceMonthStatusName, dbo.func_PlanCompleteStatus(AutoID) AS PlanStatus, MaintenanceType, PMStartMonth, CreatDate, CreatUser, ChangeDate, ChangeUser, Remarks FROM dbo.DriveMaintencePlan WHERE MaintenanceYear = @Year AND MaintenanceType IN ('Daily')), planConvertView AS (SELECT * FROM plans PIVOT ( MAX(MaintenanceType) FOR MaintenanceMonthName IN ([Jan], [Feb], [Mar], [Apr], [May], [Jun], [Jul], [Aug], [Sep], [Oct], [Nov], [Dec] ) ) AS pvt PIVOT(MAX(PlanStatus) FOR MaintenanceMonthStatusName IN ([JanStatus], [FebStatus], [MarStatus], [AprStatus], [MayStatus], [JunStatus], [JulStatus], [AugStatus], [SepStatus], [OctStatus], [NovStatus], [DecStatus] ) ) AS pvt2), planview AS (SELECT di.AutoID AS EquipmentID, di.EquipmentID AS DisplayEquipmentID, di.EquipmentName, di.MaintenanceFormVersion, ISNULL(mf.VersionCode, '') AS VersionCode, tbl.CreatDate, tbl.CreatUser, lst.ChangeDate, lst.ChangeUser, tbl.CompleteDate, tbl.MaintenanceYear, lst.PMStartMonth, lst.Remarks, MAX(tbl.Jan) AS Jan, MAX(tbl.Feb) AS Feb, MAX(tbl.Mar) AS Mar, MAX(tbl.Apr) AS Apr, MAX(tbl.May) AS May, MAX(tbl.Jun) AS Jun, MAX(tbl.Jul) AS Jul, MAX(tbl.Aug) AS Aug, MAX(tbl.Sep) AS Sep, MAX(tbl.Oct) AS Oct, MAX(tbl.Nov) AS Nov, MAX(tbl.[Dec]) AS Dec, MAX(tbl.JanStatus) AS JanStatus, MAX(tbl.FebStatus) AS FebStatus, MAX(tbl.MarStatus) AS MarStatus, MAX(tbl.AprStatus) AS AprStatus, MAX(tbl.MayStatus) AS MayStatus, MAX(tbl.JunStatus) AS JunStatus, MAX(tbl.JulStatus) AS JulStatus, MAX(tbl.AugStatus) AS AugStatus, MAX(tbl.SepStatus) AS SepStatus, MAX(tbl.OctStatus) AS OctStatus, MAX(tbl.NovStatus) AS NovStatus, MAX(tbl.DecStatus) AS DecStatus FROM planConvertView tbl LEFT JOIN ( SELECT ROW_NUMBER() OVER (PARTITION BY dmp.EquipmentID, dmp.MaintenanceYear ORDER BY dmp.ChangeDate DESC ) AS Nb, dmp.EquipmentID, dmp.MaintenanceYear, dmp.PMStartMonth, dmp.ChangeDate, dmp.ChangeUser, dmp.CompleteDate, dmp.Remarks FROM dbo.DriveMaintencePlan dmp WHERE dmp.MaintenanceType IN ('Daily') ) lst ON tbl.EquipmentID = lst.EquipmentID AND tbl.MaintenanceYear = lst.MaintenanceYear AND lst.Nb = 1 INNER JOIN dbo.DriveInformation di ON di.AutoID = tbl.EquipmentID LEFT JOIN dbo.MaintenanceFormVersion mf ON di.MaintenanceFormVersion = mf.AutoID GROUP BY di.AutoID, di.EquipmentID, di.EquipmentName, di.MaintenanceFormVersion, mf.VersionCode, tbl.CreatDate, tbl.CreatUser, lst.ChangeDate, lst.ChangeUser, tbl.CompleteDate, tbl.MaintenanceYear, lst.PMStartMonth, lst.Remarks) SELECT t1.EquipmentID, t1.DisplayEquipmentID, t1.EquipmentName, t1.MaintenanceFormVersion, t1.VersionCode, t1.CreatDate, t1.CreatUser, t1.ChangeDate, t1.ChangeUser, t1.CompleteDate, t1.MaintenanceYear, CAST(CONVERT(date, t1.PMStartMonth) AS VARCHAR(7)) AS PMStartMonth, t1.Remarks, t1.Jan, t1.Feb, t1.Mar, t1.Apr, t1.May, t1.Jun, t1.Jul, t1.Aug, t1.Sep, t1.Oct, t1.Nov, t1.Dec, t1.JanStatus, t1.FebStatus, t1.MarStatus, t1.AprStatus, t1.MayStatus, t1.JunStatus, t1.JulStatus, t1.AugStatus, t1.SepStatus, t1.OctStatus, t1.NovStatus, t1.DecStatus, t2.RealName AS CreatUserName, t3.RealName AS ChangeUserName FROM planview t1 LEFT JOIN dbo.UserInfo t2 ON t1.CreatUser = t2.AutoID LEFT JOIN dbo.UserInfo t3 ON t1.ChangeUser = t3.AutoID WHERE ( (@Keyword = '' OR @Keyword IS NULL) OR ( t1.DisplayEquipmentID LIKE '%' + @Keyword + '%' OR t1.EquipmentName LIKE '%' + @Keyword + '%' OR t1.Remarks LIKE '%' + @Keyword + '%' ) ); SET LANGUAGE @defaultLanguage; END;