129 lines
3.6 KiB
MySQL
129 lines
3.6 KiB
MySQL
|
USE [DriveMaintenance]
|
|||
|
GO
|
|||
|
|
|||
|
IF EXISTS
|
|||
|
(
|
|||
|
SELECT 1
|
|||
|
FROM INFORMATION_SCHEMA.VIEWS
|
|||
|
WHERE TABLE_SCHEMA = 'dbo'
|
|||
|
AND TABLE_NAME = 'View_YearsMaintenancePlansExport'
|
|||
|
)
|
|||
|
BEGIN
|
|||
|
DROP VIEW [dbo].[View_YearsMaintenancePlansExport];
|
|||
|
END;
|
|||
|
GO
|
|||
|
|
|||
|
CREATE VIEW [dbo].[View_YearsMaintenancePlansExport]
|
|||
|
AS
|
|||
|
SELECT t1.EquipmentID,
|
|||
|
t1.EquipmentName,
|
|||
|
t1.Specification,
|
|||
|
t1.Manufacturer,
|
|||
|
t1.SerialNumber,
|
|||
|
t1.UsingDate,
|
|||
|
t1.Totalcapacity,
|
|||
|
t1.[Weight],
|
|||
|
t1.EquipmentCategory,
|
|||
|
t1.EquipmentOriginalvalue,
|
|||
|
CASE t1.EquipmentStatus
|
|||
|
WHEN 1 THEN
|
|||
|
'运行中'
|
|||
|
ELSE
|
|||
|
'停用'
|
|||
|
END AS EquipmentStatus,
|
|||
|
t1.WarrantyPeriod,
|
|||
|
t1.InstallationLocation,
|
|||
|
t1.OwningUnit,
|
|||
|
t1.OperatingParameters,
|
|||
|
t2.MaintenanceYear,
|
|||
|
t2.Jan,
|
|||
|
t2.Feb,
|
|||
|
t2.Mar,
|
|||
|
t2.Apr,
|
|||
|
t2.May,
|
|||
|
t2.Jun,
|
|||
|
t2.Jul,
|
|||
|
t2.Aug,
|
|||
|
t2.Sep,
|
|||
|
t2.Oct,
|
|||
|
t2.Nov,
|
|||
|
t2.Dec,
|
|||
|
lst.PMStartMonth,
|
|||
|
t1.Remarks AS DriveRemarks,
|
|||
|
lst.Remarks AS PlanRemarks,
|
|||
|
rt.RootName
|
|||
|
FROM dbo.DriveInformation AS t1
|
|||
|
INNER JOIN View_DeviceRoot rt
|
|||
|
ON t1.AutoID = rt.AutoID
|
|||
|
INNER JOIN
|
|||
|
(
|
|||
|
SELECT di.AutoID AS EquipmentID,
|
|||
|
di.EquipmentID AS DisplayEquipmentID,
|
|||
|
di.EquipmentName,
|
|||
|
tbl.MaintenanceYear,
|
|||
|
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]
|
|||
|
FROM
|
|||
|
(
|
|||
|
SELECT pvt.AutoID,
|
|||
|
EquipmentID,
|
|||
|
MaintenanceYear,
|
|||
|
[1] AS Jan,
|
|||
|
[2] AS Feb,
|
|||
|
[3] AS Mar,
|
|||
|
[4] AS Apr,
|
|||
|
[5] AS May,
|
|||
|
[6] AS Jun,
|
|||
|
[7] AS Jul,
|
|||
|
[8] AS Aug,
|
|||
|
[9] AS Sep,
|
|||
|
[10] AS Oct,
|
|||
|
[11] AS Nov,
|
|||
|
[12] AS [Dec]
|
|||
|
FROM dbo.DriveMaintencePlan
|
|||
|
PIVOT
|
|||
|
(
|
|||
|
MAX(MaintenanceType)
|
|||
|
FOR MaintenanceMonth IN ([1], [2], [3], [4], [5], [6], [7], [8], [9], [10], [11], [12])
|
|||
|
) AS pvt
|
|||
|
) AS tbl
|
|||
|
LEFT JOIN dbo.DriveInformation di
|
|||
|
ON tbl.EquipmentID = di.AutoID
|
|||
|
GROUP BY di.AutoID,
|
|||
|
di.EquipmentID,
|
|||
|
di.EquipmentName,
|
|||
|
tbl.MaintenanceYear
|
|||
|
) t2
|
|||
|
ON t1.AutoID = t2.EquipmentID
|
|||
|
INNER 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.PlanStatus = 'A' AND dmp.MaintenanceType IN ( 'Annual', 'Quarterly', 'Semi-an', 'Monthly' )
|
|||
|
) lst
|
|||
|
ON t2.EquipmentID = lst.EquipmentID
|
|||
|
AND t2.MaintenanceYear = lst.MaintenanceYear
|
|||
|
AND lst.Nb = 1
|
|||
|
GO
|
|||
|
|
|||
|
|