DeviceManager/DeviceRepair.DataAccess/Script/5.0/Proc/proc_EquipmentPlanIsComplete.sql
2024-08-08 16:46:02 +08:00

221 lines
8.6 KiB
Transact-SQL
Raw Permalink Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

USE DriveMaintenance;
GO
IF OBJECT_ID('proc_EquipmentPlanIsComplete', 'P') IS NOT NULL
BEGIN
DROP PROCEDURE [dbo].[proc_EquipmentPlanIsComplete];
END;
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author: 蔡峰
-- Create date: 2024-8-5
-- Description: 判断当前开工设备是否存在未完成的保养计划
-- =============================================
CREATE PROCEDURE [dbo].[proc_EquipmentPlanIsComplete] @EquipmentDisplayID VARCHAR(50)
AS
BEGIN
BEGIN TRY
DECLARE @planId INT,
@devid INT,
@MaintenanceType NVARCHAR(50),
@MaintenanceMonth INT;
/* 检查是否当日跳过校验 */
IF EXISTS
(
SELECT *
FROM dbo.DriveMaintencePlan pln WITH (NOLOCK)
INNER JOIN dbo.DriveInformation dev WITH (NOLOCK)
ON pln.EquipmentID = dev.AutoID
INNER JOIN dbo.EquipmentJumpPlanCheck jum WITH (NOLOCK)
ON jum.EquipmentAutoID = dev.AutoID
WHERE pln.AutoID = @planId
AND DATEDIFF(DAY, jum.CheckDate, GETDATE()) = 0
)
BEGIN
RETURN;
END;
/* 游标循环 */
DECLARE cursor_plan CURSOR FOR
SELECT pl.AutoID,
dev.AutoID,
pl.MaintenanceType,
pl.MaintenanceMonth
FROM dbo.DriveMaintencePlan pl WITH (NOLOCK)
INNER JOIN dbo.DriveInformation dev WITH (NOLOCK)
ON pl.EquipmentID = dev.AutoID
WHERE dev.EquipmentID = @EquipmentDisplayID
AND pl.PlanStatus = 'A'
AND pl.MaintenanceType IS NOT NULL
AND DATEFROMPARTS(pl.MaintenanceYear, pl.MaintenanceMonth, 1)
BETWEEN DATEADD(MONTH, -2, GETDATE()) AND GETDATE();
OPEN cursor_plan;
FETCH NEXT FROM cursor_plan
INTO @planId,
@devid,
@MaintenanceType,
@MaintenanceMonth;
WHILE @@FETCH_STATUS = 0
BEGIN
IF (@MaintenanceType = 'Daily')
BEGIN
SELECT MaintenanceDay,
Banci,
IsComplete
INTO #ScheduleDetail
FROM dbo.func_GetDailyPlanProccScheduleDetail(@planId);
/* 没有获取到点检表信息 */
IF NOT EXISTS (SELECT 1 FROM #ScheduleDetail)
BEGIN
RAISERROR('设备:%s存在保养类型%s ,未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID, @MaintenanceType);
RETURN -1;
END;
ELSE
BEGIN
/* 存在未完成的历史日保养计划 */
IF EXISTS
(
SELECT 1
FROM #ScheduleDetail
WHERE MaintenanceDay < CAST(GETDATE() AS DATE)
AND IsComplete = 0
)
BEGIN
RAISERROR('设备:%s存在保养类型%s ,未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID, @MaintenanceType);
RETURN -1;
END;
ELSE
BEGIN
DECLARE @BanciName NVARCHAR(200);
SELECT @BanciName = COALESCE(@BanciName + ', ', '') + CASE Banci
WHEN 1 THEN
'早班'
WHEN 2 THEN
'中班'
ELSE
'夜班'
END
FROM #ScheduleDetail
WHERE MaintenanceDay = CAST(GETDATE() AS DATE)
AND Banci < @Banci
AND IsComplete = 0;
IF @BanciName IS NOT NULL
BEGIN
RAISERROR('设备:%s当日存在未完成AM点检%s保养,请先完成保养 ', 16, 1, @EquipmentDisplayID, @BanciName);
RETURN -1;
END;
ELSE
BEGIN
/* 前班次已点检,判断当前班次点检情况 */
IF EXISTS
(
SELECT 1
FROM #ScheduleDetail
WHERE MaintenanceDay = CAST(GETDATE() AS DATE)
AND Banci = @Banci
AND IsComplete = 0
)
BEGIN
/* 未点检 */
DECLARE @firUseTime DATETIME;
SELECT @firUseTime = CreateOn
FROM dbo.DeviceUseRecord WITH (NOLOCK)
WHERE EquipmentId = @devid
AND Banci = @Banci
AND CheckDate = CAST(GETDATE() AS DATE);
IF @firUseTime IS NOT NULL
BEGIN
IF DATEDIFF(HOUR, @firUseTime, GETDATE()) > 4
BEGIN
RAISERROR('设备:%s当前班次未完成AM点检保养,请先完成保养 ', 16, 1, @EquipmentDisplayID);
RETURN -1;
END
ELSE
BEGIN
SET @Msg = '当前班次还未完成AM点检保养请尽快处理';
END
END;
ELSE
BEGIN
/* 日保养提醒 */
INSERT INTO dbo.DeviceUseRecord
(
EquipmentId,
EquipmentDisplayId,
CheckDate,
Banci,
CreateBy,
CreateOn,
CreateClient
)
VALUES
(@devid, @EquipmentDisplayID, CAST(GETDATE() AS DATE), @Banci, @CreateBy,
GETDATE(), @CreateClient);
SET @Msg = '当前班次还未完成AM点检保养请尽快处理';
END;
END;
END;
END;
END;
DROP TABLE #ScheduleDetail;
END;
ELSE
BEGIN
IF @MaintenanceMonth < MONTH(GETDATE())
BEGIN
IF NOT EXISTS
(
SELECT 1
FROM dbo.MaintenanceRecord
WHERE PlanPrimaryID = @planId
AND PlanType = @MaintenanceType
)
BEGIN
RAISERROR('设备:%s存在保养类型%s ,未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID, @MaintenanceType);
RETURN -1;
END;
END
END;
FETCH NEXT FROM cursor_plan
INTO @planId,
@devid,
@MaintenanceType,
@MaintenanceMonth;
END;
CLOSE cursor_plan;
DEALLOCATE cursor_plan;
END TRY
BEGIN CATCH
IF OBJECT_ID('tempdb..#ScheduleDetail') IS NOT NULL
BEGIN
DROP TABLE #ScheduleDetail;
END;
CLOSE cursor_plan;
DEALLOCATE cursor_plan;
DECLARE @ErrorMessage NVARCHAR(4000);
DECLARE @ErrorSeverity INT;
DECLARE @ErrorState INT;
SELECT @ErrorMessage = ERROR_MESSAGE(),
@ErrorSeverity = ERROR_SEVERITY(),
@ErrorState = ERROR_STATE();
IF @@TRANCOUNT > 0
ROLLBACK TRAN BIZ_ADDON_NCMR_SAVE;
RAISERROR(@ErrorMessage, @ErrorSeverity, @ErrorState);
RETURN -1;
END CATCH;
END;