DeviceManager/DeviceRepair.DataAccess/Script/5.0/Proc/proc_EquipmentPlanIsComplete.sql

212 lines
7.8 KiB
MySQL
Raw Normal View History

2024-08-05 09:21:06 +00:00
USE DriveMaintenance;
GO
IF OBJECT_ID('Proc_AnnualEquipmentMaintenanceProgram', 'P') IS NOT NULL
BEGIN
DROP PROCEDURE [dbo].[Proc_AnnualEquipmentMaintenanceProgram];
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,
@Msg NVARCHAR(MAX);
DECLARE cursor_plan CURSOR FOR
SELECT pl.AutoID,
dev.AutoID,
pl.MaintenanceType,
pl.MaintenanceMonth
FROM dbo.DriveMaintencePlan pl
INNER JOIN dbo.DriveInformation dev
ON pl.EquipmentID = dev.AutoID
WHERE dev.EquipmentID = @EquipmentDisplayID
AND pl.PlanStatus = 'A'
AND pl.MaintenanceType IS NOT NULL
AND pl.MaintenanceYear = YEAR(GETDATE())
AND pl.MaintenanceMonth <= MONTH(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 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
/* 判断当日日保养完成进度 */
IF (DATEPART(HOUR, GETDATE()) > 12)
BEGIN
/* 早班 */
IF EXISTS
(
SELECT 1
FROM #ScheduleDetail
WHERE DATEDIFF(DAY, MaintenanceDay, GETDATE()) = 0
AND Banci = 1
AND IsComplete = 0
)
BEGIN
RAISERROR('设备:%s存在当日的早班保养未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID);
RETURN -1;
END;
IF (DATEPART(HOUR, GETDATE()) > 17)
BEGIN
/* 中班 */
IF EXISTS
(
SELECT 1
FROM #ScheduleDetail
WHERE DATEDIFF(DAY, MaintenanceDay, GETDATE()) = 0
AND Banci = 2
AND IsComplete = 0
)
BEGIN
RAISERROR('设备:%s存在当日的中班保养未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID);
RETURN -1;
END;
IF (DATEPART(HOUR, GETDATE()) > 22)
BEGIN
/* 晚班 */
IF EXISTS
(
SELECT 1
FROM #ScheduleDetail
WHERE DATEDIFF(DAY, MaintenanceDay, GETDATE()) = 0
AND Banci = 3
AND IsComplete = 0
)
BEGIN
RAISERROR('设备:%s存在当日的夜班保养未完成,请先完成保养 ', 16, 1, @EquipmentDisplayID);
RETURN -1;
END;
END;
END;
END;
END;
END;
DROP TABLE #ScheduleDetail;
END;
ELSE
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;
FETCH NEXT FROM cursor_plan
INTO @planId,
@devid,
@MaintenanceType,
@MaintenanceMonth;
END;
CLOSE cursor_plan;
DEALLOCATE cursor_plan;
--/* 日保养提醒 */
--SELECT dt.MaintenanceDay,
-- CASE
-- WHEN dt.Banci = 1 THEN
-- DATEADD(HOUR, 12, dt.MaintenanceDay)
-- WHEN dt.Banci = 2 THEN
-- DATEADD(HOUR, 17, dt.MaintenanceDay)
-- WHEN dt.Banci = 3 THEN
-- DATEADD(HOUR, 22, dt.MaintenanceDay)
-- END AS LastCompleteDate,
-- dt.Banci,
-- dt.IsComplete
--FROM dbo.DriveMaintencePlan pln
-- INNER JOIN dbo.DriveInformation dev
-- ON pln.EquipmentID = dev.AutoID
-- CROSS APPLY dbo.func_GetDailyPlanProccScheduleDetail(pln.AutoID) dt
--WHERE dev.EquipmentID = @EquipmentDisplayID
-- AND pln.MaintenanceType = 'Daily'
-- AND pln.MaintenanceYear = YEAR(GETDATE())
-- AND pln.MaintenanceMonth = MONTH(GETDATE())
-- AND DATEDIFF(DAY, GETDATE(), dt.MaintenanceDay) = 0;
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;