New DBA Inventory – Server Disk Info

This is a multi-part series on my newly created DBA Inventory system. The main page with a table of contents to link to all the posts is located here

The previous post discussed Server Details, things like Memory, CPU’s, Cores, BIOS, Operating System details using WMI Calls. This next post is another poll of Server level (Operating System) type detail… Disk Info.

This Powershell “poller” grabs disk info such as the Drive Letter, the Disk Model, the Partition, a Description, if it’s a Primary Partition, the Volume Name, if it’s SAN attached, if it’s a Mount Point, Disk Size, Disk Free Space, and a Serial Number. It stores all of this in a history table by an “Audit Date”. That table is named “DiskInfo”!

CREATE TABLE [dbo].[DiskInfo](
	[ServerName] [varchar](256) NOT NULL,
	[DiskName] [varchar](256) NOT NULL,
	[AuditDt] [datetime] NOT NULL,
	[Model] [varchar](256) NULL,
	[DiskPartition] [varchar](256) NULL,
	[Description] [varchar](256) NULL,
	[PrimaryPartition] [bit] NULL,
	[VolumeName] [varchar](256) NULL,
	[Drive] [varchar](128) NULL,
	[SanAttached] [bit] NULL,
	[MountPoint] [bit] NULL,
	[DiskSizeMB] [bigint] NULL,
	[DIskFreeMB] [bigint] NULL,
	[SerialNumber] [varchar](128) NULL,
 CONSTRAINT [PK_DiskInfo] PRIMARY KEY CLUSTERED 
(
	[ServerName] ASC,
	[DiskName] ASC,
	[AuditDt] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, FILLFACTOR = 90) ON [PRIMARY]
) ON [PRIMARY]

GO

The powershell itself actually only queries my Helper Database installed on every instance – named DBATools. Each instance has a job that runs nightly to get the local disk information. I had originally worked on a centralized script that polled via WMI but it was slow and cumbersome to run in my environment. This is much faster. So the central polling script is here, and it’s pretty simple.

[void] [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO")

if (Get-PSSnapin -Registered -Name SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue )
{
	Add-PSSnapin SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue
	Add-PSSnapin SqlServerProviderSnapin100 -ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}
elseif (Get-Module sqlps -ListAvailable -ErrorAction SilentlyContinue)
{
	Import-Module sqlps #-ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}	
else
{
	import-module "C:\DBATools\dbatoolsPre2008.psm1"  -ErrorAction SilentlyContinue
}

Import-Module "C:\DBATools\DBATOOLSCommon.psm1"

$dbaToolsServer = "CS-SQL-INFRAMONITORING-US-DEV-001"
$inventoryDB = "Inventory"

Function GetDiskInfo ($serverName, $sourceDB, $altCredential, $runDt)
{

	$DiskInfo = New-Object System.Data.DataTable
	[void]$DiskInfo.Columns.Add("ServerName", "System.String")
	[void]$DiskInfo.Columns.Add("DiskName", "System.String")
	[void]$DiskInfo.Columns.Add("AuditDt", "System.DateTime")
	[void]$DiskInfo.Columns.Add("Model", "System.String")
	[void]$DiskInfo.Columns.Add("DiskPartition", "System.String")
	[void]$DiskInfo.Columns.Add("Description", "System.String")
	[void]$DiskInfo.Columns.Add("PrimaryPartition", "System.Int32")
	[void]$DiskInfo.Columns.Add("VolumeName", "System.String")
	[void]$DiskInfo.Columns.Add("Drive", "System.String")
	[void]$DiskInfo.Columns.Add("SanAttached", "System.Int32")
	[void]$DiskInfo.Columns.Add("MountPoint", "System.Int32")
	[void]$DiskInfo.Columns.Add("DiskSizeMB", "System.String")
	[void]$DiskInfo.Columns.Add("DiskFreeMB", "System.String")
	[void]$DiskInfo.Columns.Add("SerialNumber", "System.String")

	$sqlQuery = "
		SELECT [ServerName]
			  ,[DiskName]
			  ,[AuditDt]
			  ,[Model]
			  ,[DiskPartition]
			  ,[Description]
			  ,[PrimaryPartition]
			  ,[VolumeName]
			  ,[Drive]
			  ,[SanAttached]
			  ,[MountPoint]
			  ,[DiskSizeMB]
			  ,[DIskFreeMB]
			  ,[SerialNumber]
		  FROM  [DiskInfo]
	"

	if ($altCredential -ne $null) {
		write-host "Using Alt Credentials!"

		$user=$altCredential.UserName
		$pass = $altCredential.GetNetworkCredential().Password
		$splat = @{
			UserName = $user
			Password = $pass
			ServerInstance = $serverName
			Database = $sourceDB
			Query = $sqlQuery
		}
		$diskQuery = Invoke-SqlCmd @splat 
	} else {
		$diskQuery = QuerySql $servername $sourceDB $sqlQuery 60000
	}
	foreach ($row in $diskQuery)
	{
			$newRow = $DiskInfo.NewRow()
			$newRow["ServerName"] = $row.Servername
			$newRow["DiskName"] = $row.DiskName
			$newRow["AuditDt"] = [DateTime]$runDt
			$newRow["Model"] = $row.Model
			$newRow["DiskPartition"] = $row.DiskPartition
			$newRow["Description"] = $row.Description
			$newRow["PrimaryPartition"] = $row.PrimaryPartition
			$newRow["VolumeName"] = $row.VolumeName
			$newRow["Drive"] = $row.Drive
			$newRow["SanAttached"] = $row.SanAttached
			$newRow["MountPoint"] = $row.MountPoint
			$newRow["DiskSizeMB"] = $row.DiskSizeMB
			$newRow["DiskFreeMB"] = $row.DiskFreeMB
			$newRow["SerialNumber"] = $row.SerialNumber
			$DiskInfo.Rows.Add($newRow)
	}

	#$diskInfo	

	try
	{
		if ($DiskInfo.Rows.Count -gt 0) {
	
			$cn = new-object System.Data.SqlClient.SqlConnection("Data Source=$dbaToolsServer;Integrated Security=SSPI;Initial Catalog=$inventoryDB");
			$cn.Open()
			$bc = new-object ("System.Data.SqlClient.SqlBulkCopy") $cn
			$bc.DestinationTableName = "DiskInfo"
			$bc.WriteToServer($DiskInfo)
			$cn.Close()
		}
	}
	catch [System.Exception]
	{
		$errVal = $_.Exception.GetType().FullName + " - " + $_.FullyQualifiedErrorID
		Write-Host "Insert Error Error $serverName"
		Write-Host $errVal
		$errCount ++
	}
}


###########################################################################################
#
#		MAIN
#
###########################################################################################

$startDate = get-date
$runDt = Get-Date -format "yyyy-MM-dd HH:00:00"

#Get-ClusteredDiskInfo "NAT317DBS" $runDt
#EXIT

$sqlQuery = @"
		SELECT [InstanceName] = ID.InstanceName, 
			[DBAToolsDB] = DD.DatabaseName,
			[UName] = AC.Uname,
			[PWord] = AC.PWord
		FROM InstanceDetails ID
		LEFT OUTER JOIN DatabaseDetails DD
			ON ID.InstanceName = DD.InstanceName
		LEFT OUTER JOIN [AltSqlCredentials] AC
			ON ID.InstanceName = AC.instancename
			and AC.[SourceServerNetBIOS] = (SELECT SERVERPROPERTY('ComputerNamePhysicalNetBIOS'))
		WHERE ID.Retired = 0
		AND ID.LicenseOnly = 0
		AND DD.DatabaseName like 'DBATools%'
"@

$clusteredServers = QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

foreach ($instance in $clusteredServers)
{
	$instanceName = $instance[0]
	$sourceDB = $instance[1]
	$user = $instance[2]
	$pass = $instance[3]

	$altCredential = $null
	if (-not(([DBNull]::Value).Equals($user)) ) {
		write-host "Found alt credential for $instanceName"
		$pass = $pass|ConvertTo-SecureString 
		$altCredential = New-Object -TypeName System.Management.Automation.PsCredential `
			-ArgumentList $user, $pass
	}

	$instanceName
	GetDiskInfo $instanceName $sourceDB $altCredential $runDt
}

$endDate = get-date
$sqlQuery = "INSERT INTO MonitoringJobStatus 
		(JOBNAME, STATUS, STARTDT, ENDDT, RANGESTARTDT, RANGEENDDT, ERROR)
		VALUES
		('DISKINFO','C','$startDate', '$endDate', '', '', '')"



QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

exit

This query gets the list of instances to poll and also introduces the concept of a SQL Login credential that’s stored as a Secure String to use a SQL Login to connect rather than the AD Credential (for servers not joined to the domain).

$sqlQuery = @"
		SELECT [InstanceName] = ID.InstanceName, 
			[DBAToolsDB] = DD.DatabaseName,
			[UName] = AC.Uname,
			[PWord] = AC.PWord
		FROM InstanceDetails ID
		LEFT OUTER JOIN DatabaseDetails DD
			ON ID.InstanceName = DD.InstanceName
		LEFT OUTER JOIN [AltSqlCredentials] AC
			ON ID.InstanceName = AC.instancename
			and AC.[SourceServerNetBIOS] = (SELECT SERVERPROPERTY('ComputerNamePhysicalNetBIOS'))
		WHERE ID.Retired = 0
		AND ID.LicenseOnly = 0
		AND DD.DatabaseName like 'DBATools%'
"@

The function GetDiskInfo just creates a new data table, queries the local DBATools..DiskInfo table and uses the credentials if they exist. It then bulk uploads that data into the Inventory table.

The local DiskInfo table is identical, its just in the DBATools database on every instance. So let’s look at the Powershell script that’s on each local server as part of the DBATools installation.

#
#	GetDiskSanInfo.ps1
#	
#	This script determines for SAN that is attached whether 
#	it is a mount point and whether it is replicated.
#
#	DiskExt.exe is used to determine which physical disk a mount point resides on.
#	inq.wnt.exe is used to determine whether a given SAN volume is replicated.
#
#	The dbo.DiskInfo table in DBATools is updated with this information. From
#	there the DB Inventory service will read it and update the DBInv database.
#

if (Get-PSSnapin -Registered -Name SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue )
{
	Add-PSSnapin SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue
	Add-PSSnapin SqlServerProviderSnapin100 -ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}
elseif (Get-Module sqlps -ListAvailable -ErrorAction SilentlyContinue)
{
	Import-Module sqlps -ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}	
else
{
	import-module "C:\DBATools\dbatoolsPre2008.psm1"  -ErrorAction SilentlyContinue
}
Import-Module "C:\DBATools\DBATOOLSCommon.psm1"

$scriptPath = split-path -parent $MyInvocation.MyCommand.Definition

$dbaToolsServer = "CS-SQL-INFRAMONITORING-US-DEV-001"
$SQLName = $args[0]
if ($SQLName -ne $null)
{ $dbaToolsServer = $SQLName }

if (Get-Module FailoverClusters -ListAvailable -ErrorAction SilentlyContinue)
{  
	Import-Module FailoverClusters	
	$clusterName = GET-Cluster
	$physicalName = $clusterName.Name.toUpper()
} else {
	$physicalName = (hostname).toUpper()
}


$runDt = Get-Date -format "MM/dd/yyyy HH:00:00"

# this is the table that will hold the data during execution
$serverDisk = New-Object System.Data.DataTable
[void]$serverDisk.Columns.Add("ServerName", "System.String")
[void]$serverDisk.Columns.Add("DiskName", "System.String")
[void]$serverDisk.Columns.Add("AuditDt", "System.DateTime")
[void]$serverDisk.Columns.Add("Model", "System.String")
[void]$serverDisk.Columns.Add("DiskPartition", "System.String")
[void]$serverDisk.Columns.Add("Description", "System.String")
[void]$serverDisk.Columns.Add("PrimaryPartition", "System.Boolean")
[void]$serverDisk.Columns.Add("VolumeName", "System.String")
[void]$serverDisk.Columns.Add("Drive", "System.String")
[void]$serverDisk.Columns.Add("SanAttached", "System.Boolean")
[void]$serverDisk.Columns.Add("MountPoint", "System.Boolean")
[void]$serverDisk.Columns.Add("DiskSizeMB", "System.Int64")
[void]$serverDisk.Columns.Add("DiskFreeMB", "System.Int64")
[void]$serverDisk.Columns.Add("SerialNumber", "System.String")
                
# WMI data
$wmi_diskdrives = Get-WmiObject -Class Win32_DiskDrive
$wmi_mountpoints = Get-WmiObject -Class Win32_Volume -Filter "DriveType=3 AND DriveLetter IS NULL AND NOT Name like '\\\\?\\Volume%'" | Select $WMI_DiskMountProps
                
$AllDisks = @()
$DiskElements = @('ComputerName','Disk','Model','Partition','Description','PrimaryPartition','VolumeName','Drive', 'SanAttached', 'MountPoint', 'DiskSize','FreeSpace','DiskType','SerialNumber')
                foreach ($diskdrive in $wmi_diskdrives) 
                {
                    $partitionquery = "ASSOCIATORS OF {Win32_DiskDrive.DeviceID=`"$($diskdrive.DeviceID.replace('\','\\'))`"} WHERE AssocClass = Win32_DiskDriveToDiskPartition"
                    $partitions = @(Get-WmiObject -Query $partitionquery)
                    foreach ($partition in $partitions)
                    {
                        $logicaldiskquery = "ASSOCIATORS OF {Win32_DiskPartition.DeviceID=`"$($partition.DeviceID)`"} WHERE AssocClass = Win32_LogicalDiskToPartition"
                        $logicaldisks = @(Get-WmiObject -Query $logicaldiskquery)
                        foreach ($logicaldisk in $logicaldisks)
                        {
				$newRow = $serverDisk.NewRow()
				$newRow["ServerName"] = $physicalName
				$newRow["DiskName"] = $logicalDisk.Name
				$newRow["AuditDt"] = [DateTime]$runDt
				$newRow["Model"] = $diskDrive.Model
				$newRow["DiskPartition"] = $partition.Name
				$newRow["Description"] = $partition.Description
				$newRow["PrimaryPartition"] = $partition.PrimaryPartition
				$newRow["VolumeName"] = $logicalDisk.volumeName
				$newRow["Drive"] = $diskDrive.Name
				$newRow["SanAttached"] = if ($diskdrive.Model.StartsWith("NETAPP")) { $TRUE } else { $FALSE }
				$newRow["MountPoint"] = $FALSE
				$newRow["DiskSizeMB"] = [math]::truncate($logicalDisk.Size / 1MB)
				$newRow["DiskFreeMB"] = [math]::truncate($logicalDisk.FreeSpace / 1MB)
				$newRow["SerialNumber"] = $diskDrive.serialNumber
				$serverDisk.Rows.Add($newRow)
                        }
                    }
                }
                # Mountpoints are weird so we do them seperate.
                if ($wmi_mountpoints)
                {
                    foreach ($mountpoint in $wmi_mountpoints)
                    {
				$newRow = $serverDisk.NewRow()
				$newRow["ServerName"] = $physicalName
				$newRow["DiskName"] = $mountpoint.Name
				$newRow["AuditDt"] = [DateTime]$runDt
				$newRow["Model"] = 'Mount Point'
				$newRow["DiskPartition"] = $DBNULL
				$newRow["Description"] = $mountpoint.Caption
				$newRow["PrimaryPartition"] = $FALSE
				$newRow["VolumeName"] = $mountpoint.Caption
				$newRow["Drive"] = [Regex]::Match($mountpoint.Caption, "(^.:)").Value
				$newRow["SanAttached"] = $TRUE
				$newRow["MountPoint"] = $TRUE
				$newRow["DiskSizeMB"] = [math]::truncate($mountpoint.Capacity / 1MB)
				$newRow["DiskFreeMB"] = [math]::truncate($mountpoint.FreeSpace / 1MB)
				$newRow["SerialNumber"] = $DBNULL
				$serverDisk.Rows.Add($newRow)
                    }
                }

$sqlCmd = "Select name from sys.databases where name like 'DBATools%'"
$dbatoolsDBName = QuerySql  $dbaToolsServer "master" $sqlCmd 

$DBAToolsDB = $dbatoolsDBName[0]

$sqlCmd = "TRUNCATE TABLE dbo.DiskInfo"
QuerySql $dbaToolsServer $DBAToolsDB $sqlCmd 

# create the connection for the bulk loads
$connString = "Data Source=$dbaToolsServer; Initial Catalog=$DBAToolsDB; Integrated Security=True; Application Name=GetSanDiskInfo.ps1; "
$sqlConn = New-Object System.Data.SqlClient.SqlConnection $connString
$sqlConn.Open()
try
{
	# upload the table to DBATools
	$bulkCopy = New-Object System.Data.SqlClient.SqlBulkCopy($sqlConn)
	$bulkCopy.DestinationTableName = "dbo.DiskInfo"
	$bulkCopy.WriteToServer($serverDisk)
}
catch [System.Exception]
{
	$errVal = $_.Exception.GetType().FullName + " - " + $_.FullyQualifiedErrorID
	Write-Host "Bulkcopy Error"
	Write-Host $errVal
	$errCount ++
}

Very similar as it creates a data table for each disk row. It also imports FailoverClusters to get the cluster name (in the case of a cluster, it stores all the disks under the Cluster Name) It then queries via WMI out to WIN32_DiskDrive and then to Win32_Volume. The filter on the Win32_Volume limits to just mount points via -Filter “DriveType=3 AND DriveLetter IS NULL AND NOT Name like ‘\\\\?\\Volume%'”.

It then uses some WMI Magic of “ASSOCIATORS OF {Win32_DiskDrive} by device ID” to get partitions, and another “ASSOCIATORS OF {Win32_DiskPartition} by device ID” to get the logical disks. This is the part that really slowed down running this from a centralized location, and forcing me to run it locally on each server.

I do some assumptions here, with the SanAttached value, if the Drive model starts with “NETAPP”, I assume it’s SAN Attached. I only have Netapp arrays in the company, so I can make that assumption. I’m sure there would be additional models, for EMC, 3Par, Dell, etc… but this works for my environment today.

I do a separate loop to load Mountpoints into the data table, and always assume they are SAN Attached.

So, if you’re astute, you’ll notice or think to yourself, if I have multiple instances on the same server, each of those DBATools databases will have a DiskInfo table and the same information in it. And then my centralized polling powershell will pull those and load them into the Inventory database…. but that table has a Primary Key on the ServerName, DiskName, and AuditDt. And you’re right it is the physical server name, or in the case of a cluster, the Virtual Computer Name of the Cluster. What I do is discard the duplicates – who needs them? Why write a bunch of logic to check for it, and not poll it, or whatnot, let the Constraint of the Clustered Primary Key do the work and disallow dupes. For example, I have one two node “active/passive” cluster that has seven instances on it. Each instance has a DBATools database, and each instance runs the local powershell script and loads the disk info for the cluster into each of the seven DBATools databases. The centralized polling script connects to each of those seven instances and attempts to load the same data seven times. It discards six of them – big deal, as long as I get one that’s all that matters…. I now have a list of all disks, volumes, mount points, total space and free space for every server that I have in my Inventory, and I have it every day. I can now trend growth rate at the server / disk layer over time.

Here’s the sample data from a single cluster of mine, with six instances on it (I group instances on a drive letter with three mountpoints under it, one for User Database Datafiles, one for User Database Tran Logs, and one for System DB’s / instance root). Just think of the trending and PowerBI charts you could make with a year’s worth of data from every SQL Server in your environment!

New DBA Inventory – Server details

This is a multi-part series on my newly created DBA Inventory system. The main page with a table of contents to link to all the posts is located here

This post will detail the start of the Inventory database schema and the powershell script(s) that poll at the Server level, to get things like number of CPUs, Cores, Memory, OS Version, Bios, Virtualization, etc.

In the Inventory database there is a table named ServerDetails. This table holds the above information. There is also a ServerDetails_Stage table that is where the powershell scripts load the data and at the end of the execution a Merge statement is run to insert new or update existing. This is something I want to enhance at some point.

There is a table named “ClusterServers” which maps the ServerName(s) to a ClusterName. About that, we use Active/Passive clusters exclusively, where all instances are on one node and the other node is there to cover any crashes on the active node, and also to speed up Windows patching. There is a Server Name column in both tables.

There is also an InstanceDetails table (and corresponding _Stage table). This table will be detailed further in the next article, but it contains details about every instance. InstanceName is the key here and is a combo of the server name and named instance, or just the server name in the case of a default instance.

There is also a ServerInstances table, which maps the InstanceDetails table to the ServerDetails table, since a single Server could have (and in our case often does) have multiple instances on it. Our clusters are all multi-instance servers as well, and here I map the instance names to the cluster name, and then use the ClusterServers to get to the physical nodes.

The aforementioned powershell script runs once daily via a SQL Agent job on the server hosting the Inventory database, and uses a proxy account designed to query WMI on the OS and also to be used to query inside the SQL Server via query statements or to use SMO calls.

Here’s the script to create these tables — Inventory_ServerDetailsSchema

The powershell script to poll and insert the data into ServerDetails_STAGE and then merge the results to the ServerDetails table.

[void] [System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO")

if (Get-PSSnapin -Registered -Name SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue )
{
	Add-PSSnapin SqlServerCmdletSnapin100 -ErrorAction SilentlyContinue
	Add-PSSnapin SqlServerProviderSnapin100 -ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}
elseif (Get-Module sqlps -ListAvailable -ErrorAction SilentlyContinue)
{
	Import-Module sqlps -ErrorAction SilentlyContinue
	import-module "C:\DBATools\dbatoolsPost2008.psm1"  -ErrorAction SilentlyContinue
}	
else
{
	import-module "C:\DBATools\dbatoolsPre2008.psm1"  -ErrorAction SilentlyContinue
}

Import-Module "C:\DBATools\DBATOOLSCommon.psm1"

$dbaToolsServer = "CS-SQL-INFRAMONITORING-US-DEV-001"
$inventoryDB = "Inventory"

Function Get-ServerInfo ($serverName)
{ 

	$serverDetails = New-Object System.Data.DataTable
	[void]$serverDetails.Columns.Add("ServerName", "System.String")
	[void]$serverDetails.Columns.Add("Manufacturer", "System.String")
	[void]$serverDetails.Columns.Add("Model", "System.String")
	[void]$ServerDetails.Columns.Add("VM", "System.Boolean")
	[void]$serverDetails.Columns.Add("TotalMemory", "System.String")
	[void]$serverDetails.Columns.Add("BiosDescription", "System.String")
	[void]$serverDetails.Columns.Add("BiosVersion", "System.String")
	[void]$serverDetails.Columns.Add("BiosSerial", "System.String")
	[void]$serverDetails.Columns.Add("OSName", "System.String")
	[void]$serverDetails.Columns.Add("Architecture", "System.String")
	[void]$serverDetails.Columns.Add("Processors", "System.String")
	[void]$serverDetails.Columns.Add("Cores", "System.String")

	$totCores=0
	[wmi]$sysInfo = get-wmiobject Win32_ComputerSystem -Namespace "root\CIMV2" -ComputerName $serverName
	[wmi]$bios = Get-WmiObject Win32_BIOS -Namespace "root\CIMV2" -computername $serverName
	[wmi]$os = Get-WmiObject Win32_OperatingSystem -Namespace "root\CIMV2" -Computername $serverName
	[array]$procs = Get-WmiObject Win32_Processor -Namespace "root\CIMV2" -Computername $serverName
	#[array]$mem = Get-WmiObject Win32_PhysicalMemory -Namespace "root\CIMV2" -ComputerName $serverName
	#[array]$nic = Get-WmiObject Win32_NetworkAdapterConfiguration -Namespace "root\CIMV2" -ComputerName $serverName | where{$_.IPEnabled -eq "True"}

	foreach ($cores in $procs.NumberOfCores)
	{
		$totCores += $cores
	}
	$vm = $FALSE
	if ($sysInfo.Model -like "*Virtual*") { $vm = $TRUE }

	$newRow = $serverDetails.NewRow()
	$newRow["ServerName"]=$serverName
	$newRow["Manufacturer"]=$sysInfo.Manufacturer;
	$newRow["Model"]=$sysInfo.Model;
	$newRow["VM"]=$vm
	$newRow["TotalMemory"]=$sysInfo.TotalPhysicalMemory;
	$newRow["BiosDescription"]=$bios.Description;
	$newRow["BiosVersion"]=$bios.SMBIOSBIOSVersion+"."+$bios.SMBIOSMajorVersion+"."+$bios.SMBIOSMinorVersion;
	$newRow["BiosSerial"]=$bios.SerialNumber;
	$newRow["OSName"]=$os.Name.Substring(0,$os.Name.IndexOf("|") -1);
	$newRow["Architecture"]=$os.OSArchitecture;
	$newRow["Processors"]=@($procs).count;
	$newRow["cores"]=$totCores;
	$serverDetails.Rows.Add($newRow)

	#$serverDetails
	if ($serverDetails.Rows.count -gt 0) {
	# create the connection for the bulk loads
		$connString = "Data Source=" + $dbaToolsServer + "; Initial Catalog=$inventoryDB; Integrated Security=True; Application Name=GetServerInfo.ps1; "
		$sqlConn = New-Object System.Data.SqlClient.SqlConnection $connString
		$sqlConn.Open()

		try
		{
		# upload the table to DBATools
			$bulkCopy = New-Object System.Data.SqlClient.SqlBulkCopy($sqlConn)
			$bulkCopy.DestinationTableName = "ServerDetails_STAGE"
			$bulkCopy.WriteToServer($serverDetails)
		}
		catch [System.Exception]
		{
			$errVal = $_.Exception.GetType().FullName + " - " + $_.FullyQualifiedErrorID
			Write-Host "Bulkcopy Error $serverName"
			Write-Host $errVal
			$errCount ++
		}
	}
 
}


###########################################################################################
#
#		MAIN
#
###########################################################################################

$startDate = get-date
$runDt = Get-Date -format "yyyy-MM-dd HH:mm:00"

QuerySql $dbaToolsServer $inventoryDB "TRUNCATE TABLE [ServerDetails_STAGE]"

$sqlQuery = @"
	SELECT [ServerName]
	FROM [ServerDetails]
	WHERE Retired= 0
	AND DomainJoined = 1
"@

$servers = QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

foreach ($serverNameRow in $servers) 
{
	$serverName = $serverNameRow[0]
	Get-ServerInfo $serverName
}

$sqlQuery = "
BEGIN TRAN
MERGE ServerDetails as T
USING ServerDetails_STAGE as S
ON (T.ServerName = S.ServerName)
WHEN NOT MATCHED BY TARGET
	THEN INSERT 
	(
		  [Servername]
		, [Manufacturer]
		, [Model]
		, [TotalMemory]
		, [BiosDescription]
		, [BiosVersion]
		, [BiosSerial]
		, [OSName]
		, [Architecture]
		, [Processors]
		, [Cores]
	) VALUES (
		  S.[Servername]
		, S.[Manufacturer]
		, S.[Model]
		, S.[TotalMemory]
		, S.[BiosDescription]
		, S.[BiosVersion]
		, S.[BiosSerial]
		, S.[OSName]
		, S.[Architecture]
		, S.[Processors]
		, S.[Cores]
	)
WHEN MATCHED AND S.Manufacturer is not null
	THEN UPDATE 
	SET T.[Servername]		= S.[Servername], 	
		T.[Manufacturer]	= S.[Manufacturer],		
		T.[Model]		= S.[Model],				
		T.[TotalMemory]		= S.[TotalMemory], 	
		T.[BiosDescription]	= S.[BiosDescription],		
		T.[BiosVersion]		= S.[BiosVersion],				
		T.[BiosSerial]		= S.[BiosSerial],				
		T.[OSName]		= S.[OSName],				
		T.[Architecture]	= S.[Architecture],		
		T.[Processors]		= S.[Processors],				
		T.[Cores]		= S.[Cores],
		T.[Mod_User]		= 'Inventory Script Update',
		T.[Mod_Dt]		= getdate()		
		;
COMMIT TRAN
"

QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

$endDate = get-date
$sqlQuery = "INSERT INTO MonitoringJobStatus 
		(JOBNAME, STATUS, STARTDT, ENDDT, RANGESTARTDT, RANGEENDDT, ERROR)
		VALUES
		('ServerDetails','C','$startDate', '$endDate', '', '', '')"



QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

exit

To talk through it quickly…
DBATools is what I call the DBAHelper database we install on every instance, and every installation gets a DBATools folder in the OS that contains helper scripts, powershell scripts, etc. It has NO relationship to DBATools.io (a great set of Powershell scripts with an overlap with the name I’ve used internally for about 3 years now).

In the following code base, we connect to the Inventory database and clear out the STAGE table. I then query the ServerDetails for a list of ServerName to poll this iteration. In the Foreach loop, I pass the server name to the function Get-ServerInfo which calls out to the server and polls the needed data.

BTW, $dbaToolsServer is defined near the head of the script as “CS-SQL-INFRAMONITORING-US-DEV-001” which is a CNAME alias to the server hosting the Inventory database. I use CNAME’s very often for connection string alias’s when helping to set up new applications – rather than give the app owners the NetBios name of the server. If we want to move databases to a new instance, we can take an outage and update the DNS record rather than go in and modify configuration strings or code. Back to the code breakout…

startDate = get-date
$runDt = Get-Date -format "yyyy-MM-dd HH:mm:00"

QuerySql $dbaToolsServer $inventoryDB "TRUNCATE TABLE [ServerDetails_STAGE]"

$sqlQuery = @"
	SELECT [ServerName]
	FROM [ServerDetails]
	WHERE Retired= 0
	AND DomainJoined = 1
"@

$servers = QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

foreach ($serverNameRow in $servers) 
{
	$serverName = $serverNameRow[0]
	Get-ServerInfo $serverName
}

In Set-ServerInfo, I build a DataTable named $serverDetails to hold the returned data from the server. I use WMI calls to get the system info, the bios, the OS, and the processor data.

	$totCores=0
	[wmi]$sysInfo = get-wmiobject Win32_ComputerSystem -Namespace "root\CIMV2" -ComputerName $serverName
	[wmi]$bios = Get-WmiObject Win32_BIOS -Namespace "root\CIMV2" -computername $serverName
	[wmi]$os = Get-WmiObject Win32_OperatingSystem -Namespace "root\CIMV2" -Computername $serverName
	[array]$procs = Get-WmiObject Win32_Processor -Namespace "root\CIMV2" -Computername $serverName

I then perform some math on the number of cores, and if the server is a VM. I add that data into the data table. Finally, I insert the data into the ServerDetails_STAGE table… I plan on pulling this functionality out of here and put it in the main body of the script…. rather than connect to Inventory and write one row of data for every server on the list. Later on you’ll see a script that I wrote more recently that does exactly this.

	if ($serverDetails.Rows.count -gt 0) {
	# create the connection for the bulk loads
		$connString = "Data Source=" + $dbaToolsServer + "; Initial Catalog=$inventoryDB; Integrated Security=True; Application Name=GetServerInfo.ps1; "
		$sqlConn = New-Object System.Data.SqlClient.SqlConnection $connString
		$sqlConn.Open()

		try
		{
		# upload the table to DBATools
			$bulkCopy = New-Object System.Data.SqlClient.SqlBulkCopy($sqlConn)
			$bulkCopy.DestinationTableName = "ServerDetails_STAGE"
			$bulkCopy.WriteToServer($serverDetails)
		}
		catch [System.Exception]
		{
			$errVal = $_.Exception.GetType().FullName + " - " + $_.FullyQualifiedErrorID
			Write-Host "Bulkcopy Error $serverName"
			Write-Host $errVal
			$errCount ++
		}
	}

Finally, once the list of servers is complete, I perform my merge statement to refresh / insert into the ServerDetails table from the ServerDetails_STAGE table. I also update some records in a Job status table.

$sqlQuery = "
BEGIN TRAN
MERGE ServerDetails as T
USING ServerDetails_STAGE as S
ON (T.ServerName = S.ServerName)
WHEN NOT MATCHED BY TARGET
	THEN INSERT 
	(
		  [Servername]
		, [Manufacturer]
		, [Model]
		, [TotalMemory]
		, [BiosDescription]
		, [BiosVersion]
		, [BiosSerial]
		, [OSName]
		, [Architecture]
		, [Processors]
		, [Cores]
	) VALUES (
		  S.[Servername]
		, S.[Manufacturer]
		, S.[Model]
		, S.[TotalMemory]
		, S.[BiosDescription]
		, S.[BiosVersion]
		, S.[BiosSerial]
		, S.[OSName]
		, S.[Architecture]
		, S.[Processors]
		, S.[Cores]
	)
WHEN MATCHED AND S.Manufacturer is not null
	THEN UPDATE 
	SET T.[Servername]		= S.[Servername], 	
		T.[Manufacturer]	= S.[Manufacturer],		
		T.[Model]		= S.[Model],				
		T.[TotalMemory]		= S.[TotalMemory], 	
		T.[BiosDescription]	= S.[BiosDescription],		
		T.[BiosVersion]		= S.[BiosVersion],				
		T.[BiosSerial]		= S.[BiosSerial],				
		T.[OSName]		= S.[OSName],				
		T.[Architecture]	= S.[Architecture],		
		T.[Processors]		= S.[Processors],				
		T.[Cores]		= S.[Cores],
		T.[Mod_User]		= 'Inventory Script Update',
		T.[Mod_Dt]		= getdate()		
		;
COMMIT TRAN
"

QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

$endDate = get-date
$sqlQuery = "INSERT INTO MonitoringJobStatus 
		(JOBNAME, STATUS, STARTDT, ENDDT, RANGESTARTDT, RANGEENDDT, ERROR)
		VALUES
		('ServerDetails','C','$startDate', '$endDate', '', '', '')"



QuerySql $dbaToolsServer $inventoryDB $sqlQuery 60000

exit

Powershell script to capture OS level properties (CPU, Cores, NIC, Memory, BIOS, OS)

I have a master post which links to a set of powershell scripts all related to this. The Master post which links to all the scripts.

This script is an updated and streamlined version of this original and ugly script

This version actually dumps out to a CSV via the “Export-CSV” command-let. It has some error handling and will check the first WMI call and skip the rest if the first one can’t connect. It has a friendly output to the screen so the user knows which server is currently being queried.

$serverList = "..\SQL Servers.txt"
#$serverList = "test.txt"
[System.Collections.ArrayList]$sysCollection = New-Object System.Collections.ArrayList($null)

foreach ($server in (Get-Content $serverList)) 
{ 
    "Collecting information from $server"
    [System.Collections.Specialized.OrderedDictionary]$si = @{}    # Blank hashtable for each iteration
    $totCores=0

    $si.Server=[string]$server;

    try
    {
        [wmi]$sysInfo = get-wmiobject Win32_ComputerSystem -Namespace "root\CIMV2" -ComputerName $server -ErrorAction Stop
        [wmi]$bios = Get-WmiObject Win32_BIOS -Namespace "root\CIMV2" -computername $server
        [wmi]$os = Get-WmiObject Win32_OperatingSystem -Namespace "root\CIMV2" -Computername $server
        [array]$procs = Get-WmiObject Win32_Processor -Namespace "root\CIMV2" -Computername $server
        [array]$mem = Get-WmiObject Win32_PhysicalMemory -Namespace "root\CIMV2" -ComputerName $server
        [array]$nic = Get-WmiObject Win32_NetworkAdapterConfiguration -Namespace "root\CIMV2" -ComputerName $server | where{$_.IPEnabled -eq "True"}


        $si.Manufacturer=[string]$sysInfo.Manufacturer;
        $si.Model=[string]$sysInfo.Model;
        $si.TotMem=[string]$sysInfo.TotalPhysicalMemory;
        $si.BiosDesc=[string]$bios.Description;
        $si.BiosVer=[string]$bios.SMBIOSBIOSVersion+"."+$bios.SMBIOSMajorVersion+"."+$bios.SMBIOSMinorVersion;
        $si.BiosSerial=[string]$bios.SerialNumber;
        $si.OSName=[string]$os.Name.Substring(0,$os.Name.IndexOf("|") -1);
        $si.Arch=[string]$os.OSArchitecture;
        $si.Processors=[string]@($procs).count;
        $si.Cores=[string]$procs[0].NumberOfCores;
        $iter=0
        while ($iter -lt 12)   #Parse through each stick of memory (arbitrary 12 Memory stick columns)
        {
            if ($mem[$iter] -ne $null) {
                $si."MemBank$iter" = [string]$mem[$iter].Capacity + "," + [string]$mem[$iter].BankLabel 
            } else {
                $si."MemBank$iter" = ""
            }
            $iter++
        }
        $iter=0
        while ($iter -lt 4)    #Parse through each NIC (arbritrary 4 Network Card columns)
        {
            $si."DHCP$iter"=[string]$nic[$iter].DHCPEnabled;
            $si."IPAddress$iter"=[string]$nic[$iter].IPAddress;
            $si."Subnet$iter"=[string]$nic[$iter].IPSubnet;
            $si."Gateway$iter"=[string]$nic[$iter].DefaultIPGateway;
            $si."Mac$iter"=[string]$nic[$iter].MacAddress;
            $iter++
        }
    }
    catch [Exception]
    {
        "Could not contact $server, skipping to next"
        Continue
    }
    finally
    {
        [void]$sysCollection.Add((New-Object PSObject -Property $si))    #Add the dictionary list to the collection
    }
}

$sysCollection | Export-CSV -path ServerInventory.csv -NoTypeInformation    #Output the collection to a CSV file

Extended Properties as a Run Book?

Perhaps Run Book isn’t the right terminology, but it’s close. So, in my environment we are a manufacturer of large equipment. We do have a centralized IT organization, but it seems to be more focused on keeping the lights on and trying to catch up on what the business purchases off the shelf or even what some groups have developed on their own.

One thing I’ve struggled with in the past two years, since this company has no defined processes (no ITIL or anything similar) and little to no documentation, has been in capturing what databases are where, who is the “Business Owner”, what the application is, and such. I’ve also started implementing DNS aliases for connection strings so that we can be more portable when moving applications, especially COTS systems where we might not have the understanding to change a set of connection strings. As you may know, I have a number of Powershell scripts that capture the specifics of the servers, instances, database properties, file locations, etc. One thing that these cannot grab are the applications and business representatives. Sure, with my two years of knowledge, I can look at a database server, look at an instance name, look at the name of the database and make a good guess at what it does, where it runs, who I should contact if there are problems or changes are planned… but when onboarding someone new, it would take an incredible amount of time for that new person to build up the same intimacy with the environment.

Previously, the approach was to take the Excel document output from the Database Properties script and add a column with “Owner” which sometimes had a name I could place with it.

Today I received a request for a new blank database via email from a quasi-developer in another location. This person is not in IT but has developed a number of supporting type applications for the local users at his manufacturing site. I thought to myself, I have all the details in this email from the requestor, maybe we should just embed this email to the excel document. But I’m lazy, and this is a very loose requirement, I could be busy, I could be in a procrastination mood and put off the follow up documentation for… well,,, ever. Next, I thought, we have a web based in-house developed tool for requesting services from IT. So I thought, hey, I could make it a requirement that a ticket be created for any new Database needed, and then just copy the ticket number into the spreadsheet. Blah, same thing, when I’m off creating a DB in SSMS, I don’t really want to have to open a spreadsheet on our SharePoint site to update that… still too manual and loose.

So, I thought, why not make it part of the “Create database” process to copy the details from the request ticket into Extended Properties inside the database. What I came up with was setting up four Key, Value pairs to start with. A Description which contains some details of the what the database is used for. An AppOwner key with the requestor name or whomever is identified as the owner. A Ticket key with the number from the request. The final required one is the ConnectionString which contains the DNS alias name created for the application to use. I kind of like it, it’s tidy and neat, and it stays with the database if I restore to a new server. The only maintenance might be to change the AppOwner if they change roles or leave the company.

I’m going to modify my above referenced powershell script to include grabbing these keys and values from every database when I run it. I’ve also been noodling a type of “Self Service portal” where power users like the requestor above can hit a web page form that would then kick off an approval work flow and I could then choose the server to deploy to and the database create and all the above documentation would be created on the fly. That would be really neat, the only flaw would be organizational changes.

In short, I’m going to make it a requirement than any new database request be filled out with our services request system, and require a description of the application just for paperwork reasons… it’s much easier to run a web based report than search a DBA’s PST file for auditing purposes. I’m going to have the DBA team start using the Extended Properties for the database to hold that. I’m going to “Extend” my powershell script to grab those properties for our documentation purposes. I may or may not work on a Provisioning Portal… I might be getting too far ahead of the rest of the IT organization here.