- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-04-2024 05:19 PM - last edited on ‎04-08-2024 09:17 AM by Mercedes_O
tblAssets.assetname,
tblSoftwareUni.softwareName As Software,
tblSoftwareUni.SoftwarePublisher As Publisher,
tblSoftware.Lastchanged,
tblSoftware.softwareVersion As Version,
b.LatestVersion,
tblAssets.lastseen
From tblAssets
Inner Join tblAssetCustom On tblAssets.AssetID = tblAssetCustom.AssetID
Inner Join tblComputersystem On tblAssets.AssetID = tblComputersystem.AssetID
Inner Join tblState On tblState.State = tblAssetCustom.State
Inner Join tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Inner Join (Select tblFileVersions.AssetID,
tblFileVersions.Found,
tblFileVersions.FilePathfull,
tblFileVersions.FileVersion,
tblFileVersions.CompanyName,
tblFileVersions.Filesize,
tblFileVersions.Lastchanged
From tblFileVersions
Where tblFileVersions.FilePathfull Like '%choco.exe' And
tblFileVersions.found = 1) haschrome On tblAssets.AssetID =
haschrome.AssetID
Inner Join (Select __.SoftID,
__.Major,
__.Minor,
__.Build,
LatestVersion = __.softwareVersion
From (Select *,
r = Row_Number() Over (Partition By _.SoftID Order By _.Major Desc,
_.Minor Desc, _.Build Desc)
From (Select Distinct tblSoftware.SoftID,
Major = Convert(INT,Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
SubString(tblSoftware.softwareVersion, 1, CharIndex('.',
tblSoftware.softwareVersion) - 1)
Else ParseName(tblSoftware.softwareVersion, 3)
End),
Minor = Convert(INT,ParseName(Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
Left(tblSoftware.softwareVersion, CharIndex(' (',
tblSoftware.softwareVersion) - 1)
Else tblSoftware.softwareVersion
End, 2)),
Build = Convert(INT,ParseName(Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
Left(tblSoftware.softwareVersion, CharIndex(' (',
tblSoftware.softwareVersion) - 1)
Else tblSoftware.softwareVersion
End, 1)),
tblSoftware.softwareVersion
From tblSoftware
Inner Join tblSoftwareUni On tblSoftware.SoftID =
tblSoftwareUni.SoftID
Where tblSoftwareUni.softwareName = 'Google Chrome') _) __
Where __.r = 1) b On tblSoftware.SoftID = b.SoftID And
tblSoftware.softwareVersion <> b.LatestVersion
Where tblSoftwareUni.softwareName = 'Google Chrome' And tblState.Statename =
'Active' And tblComputersystem.Domainrole < 2
tblAssets.assetname,
tblSoftwareUni.softwareName As Software,
tblSoftwareUni.SoftwarePublisher As Publisher,
tblSoftware.Lastchanged,
tblSoftware.softwareVersion As Version,
b.LatestVersion,
tblAssets.lastseen
From tblAssets
Inner Join tblAssetCustom On tblAssets.AssetID = tblAssetCustom.AssetID
Inner Join tblComputersystem On tblAssets.AssetID = tblComputersystem.AssetID
Inner Join tblState On tblState.State = tblAssetCustom.State
Inner Join tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Inner Join (Select tblFileVersions.AssetID,
tblFileVersions.Found,
tblFileVersions.FilePathfull,
tblFileVersions.FileVersion,
tblFileVersions.CompanyName,
tblFileVersions.Filesize,
tblFileVersions.Lastchanged
From tblFileVersions
Where tblFileVersions.FilePathfull Like '%choco.exe' And
tblFileVersions.found = 1) haschoco On tblAssets.AssetID =
haschoco.AssetID
Inner Join (Select __.SoftID,
__.Major,
__.Minor,
__.Build,
LatestVersion = __.softwareVersion
From (Select *,
r = Row_Number() Over (Partition By _.SoftID Order By _.Major Desc,
_.Minor Desc, _.Build Desc)
From (Select Distinct tblSoftware.SoftID,
Major = Convert(INT,Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
SubString(tblSoftware.softwareVersion, 1, CharIndex('.',
tblSoftware.softwareVersion) - 1)
Else ParseName(tblSoftware.softwareVersion, 3)
End),
Minor = Convert(INT,ParseName(Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
Left(tblSoftware.softwareVersion, CharIndex(' (',
tblSoftware.softwareVersion) - 1)
Else tblSoftware.softwareVersion
End, 2)),
Build = Convert(INT,ParseName(Case
When CharIndex(' (', tblSoftware.softwareVersion) > 0 Then
Left(tblSoftware.softwareVersion, CharIndex(' (',
tblSoftware.softwareVersion) - 1)
Else tblSoftware.softwareVersion
End, 1)),
tblSoftware.softwareVersion
From tblSoftware
Inner Join tblSoftwareUni On tblSoftware.SoftID =
tblSoftwareUni.SoftID
Where tblSoftwareUni.softwareName = 'Mozilla Firefox') _) __
Where __.r = 1) b On tblSoftware.SoftID = b.SoftID And
tblSoftware.softwareVersion <> b.LatestVersion
Where tblSoftwareUni.softwareName = 'Mozilla Firefox' And tblState.Statename =
'Active' And tblComputersystem.Domainrole < 2
Solved! Go to Solution.
- Labels:
-
Other Report Topics
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-15-2024 09:55 PM
Hello,
I hope you are not banging your head on this. I assume you want a report that looks like this.
Below you will find the report. You can just copy and paste it as a new report.
I originally got this style of report from Lansweeper a few years back, and I just modify it to the software and versions I need.
When the newer versions come out, just update the version numbers as needed.
The current version as of 4/15/2024 is: 123.0.6312.123
Think of the version number as :
123 | 0 | 6312 | 123 |
4 | 3 | 2 | 1 |
There are two spots in the report to update the version similar to below. Notice how "3" is skipped.
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
Select Top 1000000 tblAssets.AssetID,
tblAssets.AssetName,
tblAssets.Domain,
tsysAssetTypes.AssetTypename As AssetType,
tblAssets.Username,
tblAssets.Userdomain,
tsysAssetTypes.AssetTypeIcon10 As icon,
tblAssets.IPAddress,
tblSoftwareUni.softwareName As Software,
tblSoftware.softwareVersion As Version,
tblSoftwareUni.SoftwarePublisher As Publisher,
Case
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
'Up to date'
Else 'Out of date'
End As [Patch Status],
tsysIPLocations.IPLocation,
tblAssetCustom.Manufacturer,
tblAssetCustom.Model,
tsysOS.OSname As OS,
tblAssets.SP,
tblAssets.Lastseen,
tblAssets.Lasttried,
tblSoftware.Lastchanged,
Case
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'#d4f4be'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'#d4f4be'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
'#d4f4be'
Else '#ffadad'
End As backgroundcolor
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 tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Left Join tsysOS On tsysOS.OScode = tblAssets.OScode
Where tblSoftwareUni.softwareName Like '%Google Chrome%' And
tblSoftwareUni.SoftwarePublisher Like '%Google%' And tblState.Statename =
'Active'
To use this for other program reports; replace the software name between the percent symbols, and replace the publisher between the percent symbols.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
2 weeks ago
Select Top 1000000 tblAssets.AssetID,
tblAssets.AssetName,
tblAssets.Domain,
tsysAssetTypes.AssetTypename As AssetType,
tblAssets.Username,
tblAssets.Userdomain,
tsysAssetTypes.AssetTypeIcon10 As icon,
tblAssets.IPAddress,
tblSoftwareUni.softwareName As Software,
tblSoftware.softwareVersion As Version,
tblSoftwareUni.SoftwarePublisher As Publisher,
Case
When Cast('/' + '132.0.6834.83' + '/' As HIERARCHYID) > Cast('/' +
tblSoftware.softwareVersion + '/' As HIERARCHYID) Then 'Out of date'
Else 'Up to date'
End As [Patch Status],
tsysIPLocations.IPLocation,
tblAssetCustom.Manufacturer,
tblAssetCustom.Model,
tsysOS.OSname As OS,
tblAssets.SP,
tblAssets.Lastseen,
tblAssets.Lasttried,
tblSoftware.Lastchanged,
Case
When Cast('/' + '132.0.6834.83' + '/' As HIERARCHYID) > Cast('/' +
tblSoftware.softwareVersion + '/' As HIERARCHYID) Then '#ffadad'
Else '#d4f4be'
End As backgroundcolor
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 tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Left Join tsysOS On tsysOS.OScode = tblAssets.OScode
Where tblSoftwareUni.softwareName Like '%Google Chrome%' And
tblSoftwareUni.SoftwarePublisher Like '%Google%' And tblState.Statename =
'Active'
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-15-2024 09:55 PM
Hello,
I hope you are not banging your head on this. I assume you want a report that looks like this.
Below you will find the report. You can just copy and paste it as a new report.
I originally got this style of report from Lansweeper a few years back, and I just modify it to the software and versions I need.
When the newer versions come out, just update the version numbers as needed.
The current version as of 4/15/2024 is: 123.0.6312.123
Think of the version number as :
123 | 0 | 6312 | 123 |
4 | 3 | 2 | 1 |
There are two spots in the report to update the version similar to below. Notice how "3" is skipped.
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
Select Top 1000000 tblAssets.AssetID,
tblAssets.AssetName,
tblAssets.Domain,
tsysAssetTypes.AssetTypename As AssetType,
tblAssets.Username,
tblAssets.Userdomain,
tsysAssetTypes.AssetTypeIcon10 As icon,
tblAssets.IPAddress,
tblSoftwareUni.softwareName As Software,
tblSoftware.softwareVersion As Version,
tblSoftwareUni.SoftwarePublisher As Publisher,
Case
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'Up to date'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
'Up to date'
Else 'Out of date'
End As [Patch Status],
tsysIPLocations.IPLocation,
tblAssetCustom.Manufacturer,
tblAssetCustom.Model,
tsysOS.OSname As OS,
tblAssets.SP,
tblAssets.Lastseen,
tblAssets.Lasttried,
tblSoftware.Lastchanged,
Case
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) > 123 Then
'#d4f4be'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) > 6312 Then
'#d4f4be'
When Cast(ParseName(tblSoftware.softwareVersion, 4) As int) = 123 And
Cast(ParseName(tblSoftware.softwareVersion, 2) As int) = 6312 And
Cast(ParseName(tblSoftware.softwareVersion, 1) As int) >= 123 Then
'#d4f4be'
Else '#ffadad'
End As backgroundcolor
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 tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Left Join tsysOS On tsysOS.OScode = tblAssets.OScode
Where tblSoftwareUni.softwareName Like '%Google Chrome%' And
tblSoftwareUni.SoftwarePublisher Like '%Google%' And tblState.Statename =
'Active'
To use this for other program reports; replace the software name between the percent symbols, and replace the publisher between the percent symbols.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
2 weeks ago
Select Top 1000000 tblAssets.AssetID,
tblAssets.AssetName,
tblAssets.Domain,
tsysAssetTypes.AssetTypename As AssetType,
tblAssets.Username,
tblAssets.Userdomain,
tsysAssetTypes.AssetTypeIcon10 As icon,
tblAssets.IPAddress,
tblSoftwareUni.softwareName As Software,
tblSoftware.softwareVersion As Version,
tblSoftwareUni.SoftwarePublisher As Publisher,
Case
When Cast('/' + '132.0.6834.83' + '/' As HIERARCHYID) > Cast('/' +
tblSoftware.softwareVersion + '/' As HIERARCHYID) Then 'Out of date'
Else 'Up to date'
End As [Patch Status],
tsysIPLocations.IPLocation,
tblAssetCustom.Manufacturer,
tblAssetCustom.Model,
tsysOS.OSname As OS,
tblAssets.SP,
tblAssets.Lastseen,
tblAssets.Lasttried,
tblSoftware.Lastchanged,
Case
When Cast('/' + '132.0.6834.83' + '/' As HIERARCHYID) > Cast('/' +
tblSoftware.softwareVersion + '/' As HIERARCHYID) Then '#ffadad'
Else '#d4f4be'
End As backgroundcolor
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 tblSoftware On tblAssets.AssetID = tblSoftware.AssetID
Inner Join tblSoftwareUni On tblSoftwareUni.SoftID = tblSoftware.softID
Left Join tsysOS On tsysOS.OScode = tblAssets.OScode
Where tblSoftwareUni.softwareName Like '%Google Chrome%' And
tblSoftwareUni.SoftwarePublisher Like '%Google%' And tblState.Statename =
'Active'
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-16-2024 01:32 PM
I am looking for a report that only returns out of date versions and does not show up-to-date ones at all, and that automatically detects the latest version of the specified software.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-16-2024 07:14 PM
Simple enough,
Save the report above.
After saving it, use the "Save as" button, and save it as the same report with "- Out of date"
After you save your out of date report, go to edit the report.
Find the line that shows Patch Status, and set it to out of date
click outside of the box, it will automatically set it to = 'out of date'
Save and run your report.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-16-2024 07:18 PM
Will this method automatically detect the current version? We need an automated solution that we don't have to update.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-16-2024 07:22 PM
You will have to occasionally update the version numbers.
It will automatically show out of date if the version number is below the set values.
If you need more advanced reporting, I'd get with a DBA to write some code for you.
- Mark as New
- Bookmark
- Subscribe
- Mute
- Subscribe to RSS Feed
- Permalink
- Report Inappropriate Content
‎04-16-2024 11:06 AM
Hello there!
Thanks for the assistance!