DeviceManager/DeviceRepair.DataAccess/Script/5.0/Proc/Proc_DeviceTreeViews.sql
2024-08-05 17:21:06 +08:00

216 lines
5.6 KiB
PL/PgSQL

USE DriveMaintenance;
GO
IF OBJECT_ID('Proc_DeviceTreeViews', 'P') IS NOT NULL
BEGIN
DROP PROCEDURE [dbo].[Proc_DeviceTreeViews];
END;
SET ANSI_NULLS ON;
GO
SET QUOTED_IDENTIFIER ON;
GO
-- =============================================
-- Author: 蔡峰
-- Create date: 2024年8月2日
-- Description: 获取树形结构的设备列表
-- =============================================
CREATE PROCEDURE dbo.Proc_DeviceTreeViews @RootName VARCHAR(50)
AS
BEGIN;
WITH Base
AS (SELECT t1.Route,
ISNULL(t2.ParentID, 0) AS ParentID,
ISNULL(t1.Totalcapacity, 0) AS Totalcapacity,
ISNULL(t1.Weight, 0) AS Weight,
ISNULL(t1.EquipmentOriginalvalue, 0) AS EquipmentOriginalvalue
FROM dbo.DriveInformation AS t1 WITH (NOLOCK)
LEFT JOIN dbo.DeviceRoute AS t2 WITH (NOLOCK)
ON t1.Route = t2.AutoID
WHERE t1.Route <> 0),
LevelView
AS (SELECT AutoID,
GUID AS RouteAutoId,
CAST(0x0 AS UNIQUEIDENTIFIER) AS ParentRouteId,
ParentID,
Name,
Name AS RootName,
1 AS Level
FROM dbo.DeviceRoute WITH (NOLOCK)
WHERE ParentID = 0
AND Name IN
(
SELECT col FROM dbo.SplitIn('KH,OEM', ',')
)
UNION ALL
SELECT DeviceRoute.AutoID,
DeviceRoute.GUID,
LevelView.RouteAutoId,
LevelView.ParentID,
DeviceRoute.Name,
LevelView.RootName,
LevelView.Level + 1 AS Level
FROM dbo.DeviceRoute WITH (NOLOCK)
INNER JOIN LevelView
ON LevelView.AutoID = DeviceRoute.ParentID),
Total1
AS (SELECT vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName,
vw.Level,
SUM(dev.Totalcapacity) AS Totalcapacity,
SUM(dev.Weight) AS Weight,
SUM(dev.EquipmentOriginalvalue) AS EquipmentOriginalvalue
FROM LevelView vw
LEFT JOIN dbo.DriveInformation AS dev WITH (NOLOCK)
ON vw.AutoID = dev.Route
WHERE vw.Level = 3
GROUP BY vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName,
vw.Level),
Total2
AS (SELECT vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName,
vw.Level,
SUM(tl.Totalcapacity) AS Totalcapacity,
SUM(tl.Weight) AS Weight,
SUM(tl.EquipmentOriginalvalue) AS EquipmentOriginalvalue
FROM LevelView vw
INNER JOIN Total1 tl
ON tl.ParentRouteId = vw.RouteAutoId
GROUP BY vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName,
vw.Level),
Total
AS (SELECT vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName,
SUM(tl.Totalcapacity) AS Totalcapacity,
SUM(tl.Weight) AS Weight,
SUM(tl.EquipmentOriginalvalue) AS EquipmentOriginalvalue
FROM LevelView vw
INNER JOIN Total2 tl
ON tl.ParentRouteId = vw.RouteAutoId
GROUP BY vw.AutoID,
vw.RouteAutoId,
vw.ParentRouteId,
vw.ParentID,
vw.Name,
vw.RootName
UNION ALL
SELECT Total2.AutoID,
Total2.RouteAutoId,
Total2.ParentRouteId,
Total2.ParentID,
Total2.Name,
Total2.RootName,
Total2.Totalcapacity,
Total2.Weight,
Total2.EquipmentOriginalvalue
FROM Total2
UNION ALL
SELECT Total1.AutoID,
Total1.RouteAutoId,
Total1.ParentRouteId,
Total1.ParentID,
Total1.Name,
Total1.RootName,
Total1.Totalcapacity,
Total1.Weight,
Total1.EquipmentOriginalvalue
FROM Total1)
SELECT 0 AS AutoID,
NULL AS ChangeDate,
0 AS ChangeUser,
NULL AS CreatDate,
0 AS CreatUser,
NULL AS EquipmentCategory,
NULL AS EquipmentID,
Total.Name AS EquipmentName,
Total.EquipmentOriginalvalue AS EquipmentOriginalvalue,
1 AS EquipmentStatus,
NULL AS InstallationLocation,
0 AS MaintenanceFormVersion,
NULL AS MaintenanceFormVersionName,
0 AS MaintenanceAMFormVersion,
NULL AS MaintenanceAMFormVersionName,
NULL AS Manufacturer,
NULL AS OperatingParameters,
NULL AS OwningUnit,
NULL AS Remarks,
NULL AS SerialNumber,
NULL AS Specification,
Total.Totalcapacity AS Totalcapacity,
NULL AS UsingDate,
NULL AS VersionCode,
NULL AS VersionRev,
NULL AS AMVersionCode,
NULL AS AMVersionRev,
NULL AS WarrantyPeriod,
Total.Weight AS Weight,
Total.AutoID AS Route,
Total.RouteAutoId,
Total.ParentRouteId
FROM Total
UNION ALL
SELECT t2.AutoID,
t2.ChangeDate,
t2.ChangeUser,
t2.CreatDate,
t2.CreatUser,
t2.EquipmentCategory,
t2.EquipmentID,
t2.EquipmentName,
t2.EquipmentOriginalvalue,
t2.EquipmentStatus,
t2.InstallationLocation,
t2.MaintenanceFormVersion,
pm.FormName AS MaintenanceFormVersionName,
t2.MaintenanceAMFormVersion,
am.FormName AS MaintenanceAMFormVersionName,
t2.Manufacturer,
t2.OperatingParameters,
t2.OwningUnit,
t2.Remarks,
t2.SerialNumber,
t2.Specification,
t2.Totalcapacity,
t2.UsingDate,
pm.VersionCode,
pm.VersionRev,
am.VersionCode AS AMVersionCode,
am.VersionRev AS AMVersionRev,
t2.WarrantyPeriod,
t2.Weight,
t2.AutoID AS Route,
t2.GUID AS RouteAutoId,
t1.ParentRouteId
FROM Total t1
INNER JOIN dbo.DriveInformation AS t2 WITH (NOLOCK)
LEFT JOIN dbo.MaintenanceFormVersion AS pm WITH (NOLOCK)
ON pm.AutoID = t2.MaintenanceFormVersion
LEFT JOIN dbo.MaintenanceFormVersion AS am WITH (NOLOCK)
ON am.AutoID = t2.MaintenanceAMFormVersion
ON t1.AutoID = t2.Route
WHERE t2.Route <> 0;
END;
GO