‎11-06-2018 06:15 PM
SELECT TOP 1000000
tblAssets.AssetID
,tblAssets.AssetName
,tblAssets.Domain
,tsysAssetTypes.AssetTypename AS AssetType
,tblAssets.Username
,tblAssets.Userdomain
,tsysAssetTypes.AssetTypeIcon10 AS icon
,tblAssets.Lastseen
,tblAssets.Lasttried
,tblSoftwareUni.softwareName AS Software
,AllPlatformsSoftwares.softwareVersion AS Version
,'backgroundcolor' =
CASE WHEN tblSoftwareUni.softwareName like '%ESR%' THEN
CASE
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) < CAST('/60.2.0/' AS HIERARCHYID) THEN '#ff8300'
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) >= CAST('/60.2.2/' AS HIERARCHYID) THEN '#d4f4be'
ELSE '#ffadad'
END
ELSE
CASE
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) < CAST('/62.0/' AS HIERARCHYID) THEN '#ff8300'
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) >= CAST('/62.0.3/' AS HIERARCHYID) THEN '#d4f4be'
ELSE '#ffadad'
END
END
,'vulnerability' =
CASE WHEN tblSoftwareUni.softwareName like '%ESR%' THEN
CASE
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) < CAST('/60.2.0/' AS HIERARCHYID) THEN 'older'
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) >= CAST('/60.2.2/' AS HIERARCHYID) THEN 'fixed'
ELSE 'vulnerable'
END
ELSE
CASE
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) < CAST('/62.0/' AS HIERARCHYID) THEN 'older'
WHEN CAST('/' + AllPlatformsSoftwares.softwareVersion + '/' AS HIERARCHYID) >= CAST('/62.0.3/' AS HIERARCHYID) THEN 'fixed'
ELSE 'vulnerable'
END
END
,tblSoftwareUni.SoftwarePublisher AS Publisher
,AllPlatformsSoftwares.Lastchanged
,tblAssets.IPAddress
,tsysIPLocations.IPLocation
,tblAssetCustom.Manufacturer
,tblAssetCustom.Model
,AllPlatformsOS.OSname AS OS
,tblAssets.SP
FROM tblAssets
INNER JOIN tblAssetCustom ON tblAssets.AssetID = tblAssetCustom.AssetID
INNER JOIN tsysAssetTypes ON tsysAssetTypes.AssetType = tblAssets.Assettype
INNER JOIN tsysIPLocations ON tsysIPLocations.LocationID = tblAssets.LocationID
INNER JOIN tblState ON tblState.State = tblAssetCustom.State
INNER JOIN ( SELECT [AssetID]
,[softID]
,CASE WHEN CHARINDEX(' ',[softwareVersion])>0 THEN LEFT([softwareVersion],CHARINDEX(' ',[softwareVersion],0)-1) ELSE [softwareVersion] END AS softwareVersion
,[Lastchanged]
FROM [lansweeperdb].[dbo].[tblSoftware]
UNION
SELECT [AssetID]
,[softid]
,CASE WHEN CHARINDEX(' ',[Version])>0 THEN LEFT([Version],CHARINDEX(' ',[Version],0)-1) ELSE [Version] END
,[LastChanged]
FROM [lansweeperdb].[dbo].[tblMacApplications]
UNION
SELECT [AssetID]
,[SoftwareUniID]
,CASE WHEN CHARINDEX(' ',[Version])>0 THEN LEFT([Version],CHARINDEX(' ',[Version],0)-1) ELSE [Version] END
,[LastChanged]
FROM [lansweeperdb].[dbo].[tblLinuxSoftware]) AllPlatformsSoftwares ON tblAssets.AssetID = AllPlatformsSoftwares.AssetID AND COALESCE(AllPlatformsSoftwares.softwareVersion,'') <> ''
INNER JOIN tblSoftwareUni ON tblSoftwareUni.SoftID = AllPlatformsSoftwares.softID
LEFT JOIN ( SELECT [AssetID]
,[Caption] as 'OSname'
FROM [lansweeperdb].[dbo].[tblOperatingsystem]
UNION
SELECT [AssetID]
,[SystemVersion]
FROM [lansweeperdb].[dbo].[tblMacOSInfo]
UNION
SELECT [AssetID]
,[OSRelease]
FROM [lansweeperdb].[dbo].[tblLinuxSystem]) AllPlatformsOS ON tblAssets.AssetID = AllPlatformsOS.AssetID
WHERE tblSoftwareUni.softwareName LIKE '%Mozilla Firefox%' AND
tblState.Statename = 'Active'
ORDER BY Domain,
AssetName,
Software
‎03-01-2019 05:57 PM
‎11-15-2018 07:01 PM
‎11-09-2018 11:32 AM
Experience Lansweeper with your own data. Sign up now for a 14-day free trial.
Try Now