117 lines
3.2 KiB
Transact-SQL
117 lines
3.2 KiB
Transact-SQL
USE [DriveMaintenance]
|
|
GO
|
|
|
|
DECLARE @functionName NVARCHAR(128) = N'func_GetDailyPlanProccScheduleDetail';
|
|
|
|
IF EXISTS (
|
|
SELECT 1
|
|
FROM sys.objects AS o
|
|
WHERE o.name = @functionName
|
|
AND o.type IN ('FN', 'TF')
|
|
AND o.is_ms_shipped = 0
|
|
)
|
|
BEGIN
|
|
DROP FUNCTION [dbo].[func_GetDailyPlanProccScheduleDetail]
|
|
END
|
|
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
-- =============================================
|
|
-- Author: 蔡峰
|
|
-- Create date: 2024-08-05
|
|
-- Description: 获取当前AM保养计划的计划进度
|
|
-- =============================================
|
|
CREATE FUNCTION [dbo].[func_GetDailyPlanProccScheduleDetail]
|
|
(
|
|
@PlanID INT
|
|
)
|
|
RETURNS @CompleteStausView TABLE
|
|
(
|
|
MaintenanceDay DATETIME,
|
|
Banci INT,
|
|
IsComplete INT
|
|
)
|
|
AS
|
|
BEGIN
|
|
DECLARE @FormID INT,
|
|
@TemplateJson VARCHAR(MAX),
|
|
@PlanStartDate DATETIME;
|
|
|
|
SELECT @PlanStartDate = DATEFROMPARTS(MaintenanceYear, MaintenanceMonth, 1)
|
|
FROM dbo.DriveMaintencePlan
|
|
WHERE AutoID = @PlanID;
|
|
|
|
/* 是否存在历史点检表 */
|
|
IF EXISTS
|
|
(
|
|
SELECT 1
|
|
FROM DeviceMaintenanceLog.dbo.DeviceLog
|
|
INNER JOIN dbo.DriveMaintencePlan
|
|
ON DriveMaintencePlan.EquipmentID = DeviceLog.EquipmentAutoID
|
|
WHERE DriveMaintencePlan.AutoID = @PlanID
|
|
)
|
|
BEGIN
|
|
SELECT @FormID = FormAutoID
|
|
FROM DeviceMaintenanceLog.dbo.DeviceLog
|
|
INNER JOIN dbo.DriveMaintencePlan
|
|
ON DriveMaintencePlan.EquipmentID = DeviceLog.EquipmentAutoID
|
|
WHERE DriveMaintencePlan.AutoID = @PlanID
|
|
ORDER BY OperationDate ASC;
|
|
END;
|
|
ELSE
|
|
BEGIN
|
|
SELECT @FormID = MaintenanceAMFormVersion
|
|
FROM dbo.DriveInformation
|
|
INNER JOIN dbo.DriveMaintencePlan
|
|
ON DriveMaintencePlan.EquipmentID = DriveInformation.AutoID
|
|
WHERE DriveMaintencePlan.AutoID = @PlanID;
|
|
END;
|
|
|
|
/* 模板信息 */
|
|
SELECT @TemplateJson = ContentData
|
|
FROM dbo.MaintenanceFormVersion
|
|
WHERE AutoID = @FormID;
|
|
|
|
IF (@TemplateJson IS NULL OR @TemplateJson = '')
|
|
BEGIN
|
|
RETURN;
|
|
END
|
|
|
|
/* 进度信息 */
|
|
INSERT INTO @CompleteStausView
|
|
(
|
|
MaintenanceDay,
|
|
Banci,
|
|
IsComplete
|
|
)
|
|
SELECT CONVERT(VARCHAR(15), DATEADD(DAY, t1.number, @PlanStartDate), 23) AS MaintenanceDay,
|
|
t2.Banci,
|
|
ISNULL(t3.IsComplete, 0) AS IsComplete
|
|
FROM master.dbo.spt_values t1
|
|
CROSS APPLY
|
|
OPENJSON((JSON_QUERY(@TemplateJson, '$.Operation')))
|
|
WITH
|
|
(
|
|
MaintenanceDay VARCHAR(50) '$.MaintenanceTypeValue',
|
|
Banci INT '$.BanciType',
|
|
Value VARCHAR(50) '$.Value'
|
|
) AS t2
|
|
LEFT JOIN
|
|
(
|
|
SELECT JSON_VALUE(ContentData, '$.Operation[0].BanciType') AS Banci,
|
|
JSON_VALUE(ContentData, '$.Operation[0].MaintenanceTypeValue') AS [Day],
|
|
1 AS IsComplete
|
|
FROM dbo.MaintenanceRecord
|
|
WHERE PlanPrimaryID = @PlanID
|
|
) t3
|
|
ON (t1.number + 1) = t3.Day
|
|
AND t3.Banci = t2.Banci
|
|
WHERE t1.type = 'p'
|
|
AND t1.number <= DATEDIFF(DAY, @PlanStartDate, EOMONTH(@PlanStartDate))
|
|
AND (t1.number + 1) = t2.MaintenanceDay;
|
|
RETURN;
|
|
END;
|
|
|