-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
HOSTSD-240 Keep removed servers (#126)
Add DB migration 1.0.3
- Loading branch information
Showing
18 changed files
with
2,226 additions
and
22 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
58 changes: 58 additions & 0 deletions
58
src/libs/dal/Migrations/1.0.3/Down/PostDown/01-FindFileSystemHistoryItemsByMonth.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,58 @@ | ||
CREATE OR REPLACE FUNCTION "FindFileSystemHistoryItemsByMonth"( | ||
"startDate" TIMESTAMPTZ | ||
, "endDate" TIMESTAMPTZ DEFAULT NULL | ||
, "tenantId" INT DEFAULT NULL | ||
, "organizationId" INT DEFAULT NULL | ||
, "operatingSystemItemId" INT DEFAULT NULL | ||
, "serverServiceNowKey" VARCHAR(200) DEFAULT NULL | ||
) | ||
RETURNS SETOF public."FileSystemHistoryItem" | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT DISTINCT | ||
"Id" | ||
, "ServiceNowKey" | ||
, "RawData" | ||
, "RawDataCI" | ||
, "Name" | ||
, "Label" | ||
, "Category" | ||
, "Subcategory" | ||
, "StorageType" | ||
, "MediaType" | ||
, "VolumeId" | ||
, "ClassName" | ||
, "Capacity" | ||
, "DiskSpace" | ||
, "Size" | ||
, "SizeBytes" | ||
, "UsedSizeBytes" | ||
, "AvailableSpace" | ||
, "FreeSpace" | ||
, "FreeSpaceBytes" | ||
, "CreatedOn" | ||
, "CreatedBy" | ||
, "UpdatedOn" | ||
, "UpdatedBy" | ||
, "Version" | ||
, "ServerItemServiceNowKey" | ||
, "InstallStatus" | ||
FROM ( | ||
SELECT fshi.* | ||
, ROW_NUMBER() OVER (PARTITION BY fshi."ServiceNowKey", EXTRACT(YEAR FROM fshi."CreatedOn"), EXTRACT(MONTH FROM fshi."CreatedOn") ORDER BY fshi."CreatedOn") AS "rn" | ||
FROM public."FileSystemHistoryItem" AS fshi | ||
JOIN public."FileSystemItem" AS fsi ON fshi."ServiceNowKey" = fsi."ServiceNowKey" | ||
JOIN public."ServerItem" AS si ON fsi."ServerItemServiceNowKey" = si."ServiceNowKey" | ||
WHERE fshi."InstallStatus" = 1 | ||
AND fshi."CreatedOn" >= $1 | ||
AND ($2 IS NULL OR fshi."CreatedOn" <= $2) | ||
AND ($3 IS NULL OR si."TenantId" = $3) | ||
AND ($4 IS NULL OR si."OrganizationId" = $4) | ||
AND ($5 IS NULL OR si."OperatingSystemItemId" = $5) | ||
AND ($6 IS NULL OR fshi."ServerItemServiceNowKey" = $6) | ||
) AS "sub" | ||
WHERE "rn" = 1 | ||
ORDER BY "ServiceNowKey", "CreatedOn"; | ||
END;$$ |
61 changes: 61 additions & 0 deletions
61
src/libs/dal/Migrations/1.0.3/Down/PostDown/01-FindFileSystemHistoryItemsByMonthForUser.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,61 @@ | ||
CREATE OR REPLACE FUNCTION "FindFileSystemHistoryItemsByMonthForUser"( | ||
"userId" INT | ||
, "startDate" TIMESTAMPTZ | ||
, "endDate" TIMESTAMPTZ DEFAULT NULL | ||
, "tenantId" INT DEFAULT NULL | ||
, "organizationId" INT DEFAULT NULL | ||
, "operatingSystemItemId" INT DEFAULT NULL | ||
, "serverServiceNowKey" VARCHAR(200) DEFAULT NULL | ||
) | ||
RETURNS SETOF public."FileSystemHistoryItem" | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT DISTINCT | ||
"Id" | ||
, "ServiceNowKey" | ||
, "RawData" | ||
, "RawDataCI" | ||
, "Name" | ||
, "Label" | ||
, "Category" | ||
, "Subcategory" | ||
, "StorageType" | ||
, "MediaType" | ||
, "VolumeId" | ||
, "ClassName" | ||
, "Capacity" | ||
, "DiskSpace" | ||
, "Size" | ||
, "SizeBytes" | ||
, "UsedSizeBytes" | ||
, "AvailableSpace" | ||
, "FreeSpace" | ||
, "FreeSpaceBytes" | ||
, "CreatedOn" | ||
, "CreatedBy" | ||
, "UpdatedOn" | ||
, "UpdatedBy" | ||
, "Version" | ||
, "ServerItemServiceNowKey" | ||
, "InstallStatus" | ||
FROM ( | ||
SELECT fshi.* | ||
, ROW_NUMBER() OVER (PARTITION BY fshi."ServiceNowKey", EXTRACT(YEAR FROM fshi."CreatedOn"), EXTRACT(MONTH FROM fshi."CreatedOn") ORDER BY fshi."CreatedOn") AS "rn" | ||
FROM public."FileSystemHistoryItem" AS fshi | ||
JOIN public."FileSystemItem" AS fsi ON fshi."ServiceNowKey" = fsi."ServiceNowKey" | ||
JOIN public."ServerItem" AS si ON fsi."ServerItemServiceNowKey" = si."ServiceNowKey" | ||
WHERE fshi."InstallStatus" = 1 | ||
AND fshi."CreatedOn" >= $2 | ||
AND ($3 IS NULL OR fshi."CreatedOn" <= $3) | ||
AND ($4 IS NULL OR si."TenantId" = $4) | ||
AND ($5 IS NULL OR si."OrganizationId" = $5) | ||
AND ($6 IS NULL OR si."OperatingSystemItemId" = $6) | ||
AND ($7 IS NULL OR fshi."ServerItemServiceNowKey" = $7) | ||
AND (si."TenantId" IN (SELECT "TenantId" FROM public."UserTenant" WHERE "UserId" = $1) | ||
OR si."OrganizationId" IN (SELECT "OrganizationId" FROM public."UserOrganization" WHERE "UserId" = $1)) | ||
) AS "sub" | ||
WHERE "rn" = 1 | ||
ORDER BY "ServiceNowKey", "CreatedOn"; | ||
END;$$ |
57 changes: 57 additions & 0 deletions
57
src/libs/dal/Migrations/1.0.3/Down/PostDown/01-FindServerHistoryItemsByMonth.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,57 @@ | ||
CREATE OR REPLACE FUNCTION "FindServerHistoryItemsByMonth"( | ||
"startDate" TIMESTAMPTZ | ||
, "endDate" TIMESTAMPTZ DEFAULT NULL | ||
, "tenantId" INT DEFAULT NULL | ||
, "organizationId" INT DEFAULT NULL | ||
, "operatingSystemItemId" INT DEFAULT NULL | ||
, "serviceNowKey" VARCHAR(200) DEFAULT NULL | ||
) | ||
RETURNS SETOF public."ServerHistoryItem" | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
RETURN QUERY | ||
SELECT DISTINCT | ||
"Id" | ||
, "TenantId" | ||
, "OrganizationId" | ||
, "OperatingSystemItemId" | ||
, "ServiceNowKey" | ||
, "HistoryKey" | ||
, "RawData" | ||
, "RawDataCI" | ||
, "ClassName" | ||
, "Name" | ||
, "Category" | ||
, "Subcategory" | ||
, "DnsDomain" | ||
, "Platform" | ||
, "IPAddress" | ||
, "FQDN" | ||
, "DiskSpace" | ||
, "Capacity" | ||
, "AvailableSpace" | ||
, "CreatedOn" | ||
, "CreatedBy" | ||
, "UpdatedOn" | ||
, "UpdatedBy" | ||
, "Version" | ||
, "InstallStatus" | ||
FROM ( | ||
SELECT * | ||
, ROW_NUMBER() OVER (PARTITION BY "ServiceNowKey", EXTRACT(YEAR FROM "CreatedOn"), EXTRACT(MONTH FROM "CreatedOn") ORDER BY "CreatedOn") AS "rn" | ||
FROM public."ServerHistoryItem" | ||
WHERE "InstallStatus" = 1 | ||
AND "CreatedOn" >= $1 | ||
AND ($2 IS NULL OR "CreatedOn" <= $2) | ||
AND ($3 IS NULL OR "TenantId" = $3) | ||
AND ($4 IS NULL OR "OrganizationId" = $4) | ||
AND ($5 IS NULL OR "OperatingSystemItemId" = $5) | ||
AND ($6 IS NULL OR "ServiceNowKey" = $6) | ||
) AS "sub" | ||
WHERE "rn" = 1 | ||
ORDER BY "ServiceNowKey", "CreatedOn"; | ||
END;$$ | ||
|
||
-- Use by calling | ||
-- select * from public."FindServerHistoryItemsByMonth"('2023-12-01'); |
Oops, something went wrong.