Skip to content

Commit

Permalink
Merge branch 'release/IsGTMTime'
Browse files Browse the repository at this point in the history
  • Loading branch information
Ioan-Popovici committed Aug 14, 2024
2 parents d65f518 + 5a3c6cb commit b3ebbf7
Show file tree
Hide file tree
Showing 7 changed files with 86 additions and 95 deletions.
8 changes: 4 additions & 4 deletions MEM.Zone-Dashboards/Private/ufn_CM_GetUpdateCompliance.sql
Original file line number Diff line number Diff line change
Expand Up @@ -103,7 +103,7 @@ AS
, ServiceWindowStart DATETIME
, ServiceWindowDuration INT
, ServiceWindowEnabled BIT
, IsGMTTime BIT
, IsUTCTime BIT
)

/* Populate @HealthThresholdVariables table */
Expand Down Expand Up @@ -159,7 +159,7 @@ AS
, ServiceWindowStart = NextServiceWindow.StartTime
, ServiceWindowDuration = NextServiceWindow.Duration
, ServiceWindowEnabled = ServiceWindow.Enabled
, IsGMTTime = NextServiceWindow.IsGMTTime
, IsUTCTime = NextServiceWindow.IsUTCTime
, RowNumber = DENSE_RANK() OVER (PARTITION BY CollectionMembers.ResourceID ORDER BY IIF(
NextServiceWindow.NextServiceWindow IS NULL, 1, 0), NextServiceWindow.NextServiceWindow, ServiceWindow.ServiceWindowID
) -- Order by NextServiceWindow with NULL Values last
Expand All @@ -174,14 +174,14 @@ AS
)

/* Populate MaintenanceInfo table and remove duplicates */
INSERT INTO @MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsGMTTime)
INSERT INTO @MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsUTCTime)
SELECT
ResourceID
, NextServiceWindow
, ServiceWindowStart
, ServiceWindowDuration
, ServiceWindowEnabled
, IsGMTTime
, IsUTCTime
FROM Maintenance_CTE
WHERE RowNumber = 1 -- Remove duplicates
END
Expand Down
Original file line number Diff line number Diff line change
@@ -1,8 +1,9 @@

/*
.SYNOPSIS
Gets the operating system version compliance for a Collection in MEMCM.
Gets the operating system version compliance for a Collection in ConfigMgr.
.DESCRIPTION
Gets the operating system compliance in MEMCM by Collection, operating system version and operating system type.
Gets the operating system compliance in ConfigMgr by Collection, operating system version and operating system type.
.NOTES
Requires SQL 2016.
Part of a report should not be run separately
Expand All @@ -20,24 +21,24 @@
/* #region QueryBody */

/* Testing variables !! Need to be commented for Production !! */
--DECLARE @UserSIDs AS NVARCHAR(10) = 'Disabled';
--DECLARE @CollectionID AS NVARCHAR(10) = 'VIT00984';
--DECLARE @Locale AS INT = 2;
--DECLARE @OSComplianceType AS NVARCHAR(20) = 5; --'Professional'
--DECLARE @OSComplianceVersion AS NVARCHAR(50) = '20H2';
--DECLARE @HealthThresholds AS NVARCHAR(20) = '14,40,8';
--DECLARE @Compliant AS INT = 1; --'Compliant'
--DECLARE @ServicingState AS INT = 2; --'Current'
-- DECLARE @UserSIDs AS NVARCHAR(10) = 'Disabled';
-- DECLARE @CollectionID AS NVARCHAR(10) = 'JNJ08AF9';
-- DECLARE @Locale AS INT = 2;
-- DECLARE @OSComplianceType AS NVARCHAR(20) = 4; --'Enterprise'
-- DECLARE @OSComplianceVersion AS NVARCHAR(50) = '21H2';
-- DECLARE @HealthThresholds AS NVARCHAR(20) = '14,40,8';
-- DECLARE @Compliant AS INT = 1; --'Compliant'
-- DECLARE @ServicingState AS INT = 2; --'Current'

/* Variable declaration */
DECLARE @LCID AS INT = dbo.fn_LShortNameToLCID(@Locale);
DECLARE @LastSupportedLegacyOSBuild AS INT = 9600;

/* Initialize memory tables */
DECLARE @HealthThresholdVariables TABLE (ID INT IDENTITY(1,1), Threshold INT);
DECLARE @HealthState TABLE (BitMask INT, StateName NVARCHAR(250));
DECLARE @ClientState TABLE (BitMask INT, StateName NVARCHAR(100));
DECLARE @OSNamesNormalized TABLE (OSName NVARCHAR(100), OSType INT);
DECLARE @OSServicing TABLE (StateNumber INT, StateName NVARCHAR(20));

/* Populate @HealthThresholdVariables table */
INSERT INTO @HealthThresholdVariables (Threshold)
Expand All @@ -58,8 +59,8 @@ VALUES
, (8, N'Pending Restart')
, (16, N'Update Scan Failed')
, (32, N'Update Scan Late')
, (64, N'Uptime Threshold Exeeded')
, (128, N'Free Space Threshold Exeeded')
, (64, N'Uptime Threshold Exceeded')
, (128, N'Free Space Threshold Exceeded')
, (256, N'Servicing Expired')

/* Populate ClientState table */
Expand All @@ -86,6 +87,16 @@ SELECT DISTINCT
END
FROM fn_rbac_GS_OPERATING_SYSTEM(@UserSIDs) AS OperatingSystem

/* Populate OSServicing table */
INSERT INTO @OSServicing (StateNumber, StateName)
VALUES
(0, N'Internal')
, (1, N'Insider')
, (2, N'Current')
, (3, N'Expiring Soon')
, (4, N'Expired')
, (5, N'Unknown')

/* Get device info */
;
WITH DeviceInfo_CTE
Expand Down Expand Up @@ -148,19 +159,9 @@ AS (
--Servicing Expired
+
IIF(
OSInfo.ServicingState = 4 OR (Systems.Build01 = '6.3.9600' AND CURRENT_TIMESTAMP > CONVERT(DATETIME, '2023-01-10'))
OSInfo.ServicingState = 4
, POWER(256, 1)
, IIF(
CONVERT(
INT
, (SELECT SUBSTRING(
(SELECT CAST('<t>' + REPLACE(Systems.Build01, '.','</t><t>') + '</t>' AS XML).value('/t[3]','NVARCHAR(500)'))
, 0, 6
)
)
) < @LastSupportedLegacyOSBuild
, POWER(256, 1), 0
)
, 0
)
)
, Compliant = (
Expand Down Expand Up @@ -205,34 +206,10 @@ AS (
)
, OSVersion = ISNULL(OSInfo.Version, IIF(RIGHT(OperatingSystem.Caption0, 7) = 'Preview', 'Insider Preview', NULL))
, OSBuildNumber = Systems.Build01
, OSServicingState = (
ISNULL(OSInfo.ServicingState,
CASE
WHEN Systems.Build01 = '6.3.9600'
AND CURRENT_TIMESTAMP <= CONVERT(DATETIME, '2023-01-10') THEN 3 --'Expiring Soon'
WHEN Systems.Build01 = '6.3.9600'
AND CURRENT_TIMESTAMP > CONVERT(DATETIME, '2023-01-10') THEN 4 --'Expired'
ELSE
IIF(
CONVERT(
INT
, (SELECT SUBSTRING(
(SELECT CAST('<t>' + REPLACE(Systems.Build01, '.','</t><t>') + '</t>' AS XML).value('/t[3]','NVARCHAR(500)'))
, 0, 6 --Last 6 characters
)
)
) < @LastSupportedLegacyOSBuild
, 4, 5 --'Expired', 'Unknown'
)
END
)
) --0 = 'Internal', 1 = 'Insider', 2 = 'Current', 3 = 'Expiring Soon', 4 = 'Expired', 5 = 'Unknown'
, UserDeviceAffinity = UserDeviceAffinityInfo.AssignedUser
, OSServicingState = ISNULL(OSInfo.ServicingState, 5) --0 = 'Internal', 1 = 'Insider', 2 = 'Current', 3 = 'Expiring Soon', 4 = 'Expired', 5 = 'Unknown'
, Domain = Systems.Resource_Domain_OR_Workgr0
, Country = Users.co
, Location = Users.l
, Uptime = DATEDIFF(dd, OperatingSystem.LastBootUpTime0, CURRENT_TIMESTAMP)
, LastBootTime = CONVERT(NVARCHAR(16), OperatingSystem.LastBootUpTime0, 120)
-- , LastBootTime = CONVERT(NVARCHAR(16), OperatingSystem.LastBootUpTime0, 120)
, PendingRestart = (
CASE
WHEN CombinedResources.IsClient = 0
Expand All @@ -258,7 +235,7 @@ AS (
, ClientState = IIF(CombinedResources.IsClient = 1, ClientSummary.ClientStateDescription, 'Unmanaged')
, ClientVersion = CombinedResources.ClientVersion
, LastUpdateScan = DATEDIFF(dd, UpdateScan.LastScanTime, CURRENT_TIMESTAMP)
, LastUpdateScanTime = CONVERT(NVARCHAR(16), UpdateScan.LastScanTime, 120)
-- , LastUpdateScanTime = CONVERT(NVARCHAR(16), UpdateScan.LastScanTime, 120)
, LastScanError = NULLIF(UpdateScan.LastErrorCode, 0)
FROM fn_rbac_R_System(@UserSIDs) AS Systems
JOIN fn_rbac_CombinedDeviceResources(@UserSIDs) AS CombinedResources ON CombinedResources.MachineID = Systems.ResourceID
Expand All @@ -277,21 +254,11 @@ AS (
SELECT
Version = OSLocalizedNames.Value
, ServicingState = OSServicingStates.State
FROM fn_GetWindowsServicingLocalizedNames() AS OSLocalizedNames
JOIN fn_GetWindowsServicingStates() AS OSServicingStates ON OSServicingStates.Build = Systems.Build01
FROM vSMS_Win10Dashboard AS Win10Dashboard
LEFT JOIN fn_GetWindowsServicingStates() AS OSServicingStates ON OSServicingStates.Build = Systems.Build01
WHERE OSLocalizedNames.Name = OSServicingStates.Name
AND Systems.OSBranch01 = OSServicingStates.Branch --Select only the branch of the installed OS
AND Systems.OSBranch01 = Win10Dashboard.Branch --Select only the branch of the installed OS
) AS OSInfo
OUTER APPLY (
SELECT
AssignedUser = UserMachineRelationship.UniqueUserName
FROM fn_rbac_UserMachineRelationship(@UserSIDs) AS UserMachineRelationship
WHERE UserMachineRelationship.MachineResourceID = CollectionMembers.ResourceID
AND UserMachineRelationship.CreationTime = (
SELECT MAX(UserMachineRelationshipInner.CreationTime) FROM fn_rbac_UserMachineRelationship(@UserSIDs) AS UserMachineRelationshipInner
WHERE UserMachineRelationshipInner.MachineResourceID = CollectionMembers.ResourceID
) --Select only the newest User Device Affinity
) AS UserDeviceAffinityInfo
WHERE CollectionMembers.CollectionID = @CollectionID
)

Expand All @@ -303,23 +270,24 @@ SELECT
, DeviceInfo.OperatingSystem
, DeviceInfo.OSVersion
, DeviceInfo.OSBuildNumber
, DeviceInfo.OSServicingState
, DeviceInfo.UserDeviceAffinity
, OSServicingState = (
SELECT StateName FROM @OSServicing
WHERE StateNumber = DeviceInfo.OSServicingState
)
, DeviceInfo.Domain
, DeviceInfo.Country
, DeviceInfo.Location
, DeviceInfo.Uptime
, DeviceInfo.LastBootTime
-- , DeviceInfo.LastBootTime
, DeviceInfo.PendingRestart
, DeviceInfo.FreeSpace
, DeviceInfo.ClientState
, DeviceInfo.ClientVersion
, DeviceInfo.LastUpdateScan
, DeviceInfo.LastUpdateScanTime
-- , DeviceInfo.LastUpdateScanTime
, DeviceInfo.LastScanError
FROM DeviceInfo_CTE AS DeviceInfo
WHERE Compliant IN (@Compliant)
AND OSServicingState IN (@ServicingState)
ORDER BY OperatingSystem, OSVersion

/* #endregion */
/*##=============================================*/
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,8 @@
Requires SQL 2016.
Requires ufn_CM_GetNextMaintenanceWindow sql helper function in order to display the next maintenance window.
Requires SELECT access on vSMS_AutoDeployments for smsschm_users (ConfigMgr Reporting).
Part of a report should not be run separately.LINK
Part of a report should not be run separately.
.LINK
https://MEM.Zone
.LINK
https://MEMZ.one/Dashboards
Expand All @@ -24,10 +25,11 @@

/* Testing variables !! Need to be commented for Production !! */
--DECLARE @UserSIDs AS NVARCHAR(10) = 'Disabled';
--DECLARE @CollectionID AS NVARCHAR(10) = 'SMS00001';
--DECLARE @CollectionID AS NVARCHAR(10) = 'JNJ02AEC';
--DECLARE @Locale AS INT = 2;
--DECLARE @Categories AS INT = 16777247; -- Security Updates
--DECLARE @Vendors AS INT = 16777254; -- Microsoft
--DECLARE @Groups AS INT = 97508;
--DECLARE @Categories AS INT = 31; -- Security Updates
--DECLARE @Vendors AS INT = 37; -- Microsoft
--DECLARE @Compliant AS INT = 0;
--DECLARE @Targeted AS INT = 1;
--DECLARE @Enabled AS INT = 1;
Expand All @@ -52,11 +54,22 @@ DECLARE @LCID AS INT = dbo.fn_LShortNameToLCID(@Locale);
DECLARE @HealthThresholdVariables TABLE (ID INT IDENTITY(1,1), Threshold INT);
DECLARE @HealthState TABLE (BitMask INT, StateName NVARCHAR(250));
DECLARE @ClientState TABLE (BitMask INT, StateName NVARCHAR(100));
DECLARE @GroupCIs TABLE (CI_ID INT);

/* Populate @HealthThresholdVariables table */
INSERT INTO @HealthThresholdVariables (Threshold)
SELECT VALUE FROM STRING_SPLIT(@HealthThresholds, N',')

/* Populate @GroupCIs table */
INSERT INTO @GroupCIs (CI_ID)
SELECT
CI_ID = CIRelation.ReferencedCI_ID
FROM fn_rbac_CIRelation_All(@UserSIDs) AS CIRelation
JOIN fn_rbac_AuthListInfo(@LCID, @UserSIDs) AS AuthList ON AuthList.CI_ID = CIRelation.CI_ID
WHERE CIRelation.RelationType = 1
AND AuthList.CI_ID IN (@Groups)
ORDER BY CIRelation.ReferencedCI_ID

/* Set Health Threshold variables */
DECLARE @HT_DistantMW AS INT = (SELECT Threshold FROM @HealthThresholdVariables WHERE ID = 1); -- Days
DECLARE @HT_ShortMW AS INT = (SELECT Threshold FROM @HealthThresholdVariables WHERE ID = 2); -- Minutes
Expand Down Expand Up @@ -99,7 +112,7 @@ CREATE TABLE #MaintenanceInfo (
, ServiceWindowStart DATETIME
, ServiceWindowDuration INT
, ServiceWindowEnabled INT
, IsGMTTime INT
, IsUTCTime INT
)

/* Get maintenance data */
Expand All @@ -112,7 +125,7 @@ IF @HelperFunctionExists = 1
, ServiceWindowStart = NextServiceWindow.StartTime
, ServiceWindowDuration = NextServiceWindow.Duration
, ServiceWindowEnabled = ServiceWindow.Enabled
, IsGMTTime = NextServiceWindow.IsGMTTime
, IsUTCTime = NextServiceWindow.IsUTCTime
, RowNumber = DENSE_RANK() OVER (PARTITION BY CollectionMembers.ResourceID ORDER BY IIF(
NextServiceWindow.NextServiceWindow IS NULL, 1, 0), NextServiceWindow.NextServiceWindow, ServiceWindow.ServiceWindowID
) -- Order by NextServiceWindow with NULL Values last
Expand All @@ -127,14 +140,14 @@ IF @HelperFunctionExists = 1
)

/* Populate MaintenanceInfo table and remove duplicates */
INSERT INTO #MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsGMTTime)
INSERT INTO #MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsUTCTime)
SELECT
ResourceID
, NextServiceWindow
, ServiceWindowStart
, ServiceWindowDuration
, ServiceWindowEnabled
, IsGMTTime
, IsUTCTime
FROM Maintenance_CTE
WHERE RowNumber = 1 -- Remove duplicates
END
Expand All @@ -149,7 +162,8 @@ AS (
FROM fn_rbac_R_System(@UserSIDs) AS Systems
JOIN fn_rbac_UpdateComplianceStatus(@UserSIDs) AS ComplianceStatus ON ComplianceStatus.ResourceID = Systems.ResourceID
AND ComplianceStatus.Status = 2 -- Filter on 'Required' (0 = Unknown, 1 = NotRequired, 2 = Required, 3 = Installed)
JOIN fn_rbac_ClientCollectionMembers(@UserSIDs) AS CollectionMembers ON CollectionMembers.ResourceID = ComplianceStatus.ResourceID
AND ComplianceStatus.CI_ID IN (SELECT CI_ID FROM @GroupCIs) -- Filter on Selected Update Groups
JOIN fn_rbac_ClientCollectionMembers(@UserSIDs) AS CollectionMembers ON CollectionMembers.ResourceID = Systems.ResourceID
JOIN fn_rbac_UpdateInfo(@LCID, @UserSIDs) AS UpdateCIs ON UpdateCIs.CI_ID = ComplianceStatus.CI_ID
AND UpdateCIs.IsExpired = 0 -- Filter on Expired
AND UpdateCIs.IsSuperseded IN (@Superseded) -- Filter on Superseded
Expand All @@ -167,6 +181,7 @@ AS (
LEFT JOIN fn_rbac_CITargetedMachines(@UserSIDs) AS Targeted ON Targeted.CI_ID = ComplianceStatus.CI_ID
AND Targeted.ResourceID = ComplianceStatus.ResourceID
WHERE CollectionMembers.CollectionID = @CollectionID
AND Systems.Client0 = 1 -- Filter on Managed Clients
AND IIF(Targeted.ResourceID IS NULL, 0, 1) IN (@Targeted) -- Filter on 'Targeted' or 'NotTargeted'
AND IIF(
NULLIF(@ArticleID, N'') IS NULL
Expand Down Expand Up @@ -337,7 +352,7 @@ SELECT Systems.ResourceID
AND NextServiceWindow < CURRENT_TIMESTAMP
, 1, 0 -- 1 = Open, 2 = Closed
)
, IsUTCTime = IsGMTTime
, IsUTCTime = IsUTCTime
FROM fn_rbac_R_System(@UserSIDs) AS Systems
JOIN fn_rbac_CombinedDeviceResources(@UserSIDs) AS CombinedResources ON CombinedResources.MachineID = Systems.ResourceID
JOIN fn_rbac_FullCollectionMembership(@UserSIDs) AS CollectionMembers ON CollectionMembers.ResourceID = Systems.ResourceID
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -199,7 +199,7 @@ CREATE TABLE #MaintenanceInfo (
, ServiceWindowStart DATETIME
, ServiceWindowDuration INT
, ServiceWindowEnabled INT
, IsGMTTime INT
, IsUTCTime INT
)

/* Get maintenance data */
Expand All @@ -212,7 +212,7 @@ IF @HelperFunctionExists = 1
, ServiceWindowStart = NextServiceWindow.StartTime
, ServiceWindowDuration = NextServiceWindow.Duration
, ServiceWindowEnabled = ServiceWindow.Enabled
, IsGMTTime = NextServiceWindow.IsGMTTime
, IsUTCTime = NextServiceWindow.IsUTCTime
, RowNumber = DENSE_RANK() OVER (PARTITION BY CollectionMembers.ResourceID ORDER BY IIF(
NextServiceWindow.NextServiceWindow IS NULL, 1, 0), NextServiceWindow.NextServiceWindow, ServiceWindow.ServiceWindowID
) -- Order by NextServiceWindow with NULL Values last
Expand All @@ -227,14 +227,14 @@ IF @HelperFunctionExists = 1
)

/* Populate MaintenanceInfo table and remove duplicates */
INSERT INTO #MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsGMTTime)
INSERT INTO #MaintenanceInfo(ResourceID, NextServiceWindow, ServiceWindowStart, ServiceWindowDuration, ServiceWindowEnabled, IsUTCTime)
SELECT
ResourceID
, NextServiceWindow
, ServiceWindowStart
, ServiceWindowDuration
, ServiceWindowEnabled
, IsGMTTime
, IsUTCTime
FROM Maintenance_CTE
WHERE RowNumber = 1 -- Remove duplicates
END
Expand Down Expand Up @@ -448,7 +448,7 @@ SELECT Systems.ResourceID
AND NextServiceWindow &lt; CURRENT_TIMESTAMP
, 1, 0 -- 1 = Open, 2 = Closed
)
, IsUTCTime = IsGMTTime
, IsUTCTime = IsUTCTime
FROM fn_rbac_R_System(@UserSIDs) AS Systems
JOIN fn_rbac_CombinedDeviceResources(@UserSIDs) AS CombinedResources ON CombinedResources.MachineID = Systems.ResourceID
JOIN fn_rbac_FullCollectionMembership(@UserSIDs) AS CollectionMembers ON CollectionMembers.ResourceID = Systems.ResourceID
Expand Down
Loading

0 comments on commit b3ebbf7

Please sign in to comment.