Skip to content

Commit

Permalink
Merge pull request #109 from VladDBA/dev
Browse files Browse the repository at this point in the history
Dev
  • Loading branch information
VladDBA authored Sep 26, 2023
2 parents 730e70f + bdd1da5 commit 745f017
Show file tree
Hide file tree
Showing 5 changed files with 210 additions and 41 deletions.
6 changes: 4 additions & 2 deletions LICENSE
Original file line number Diff line number Diff line change
Expand Up @@ -3,9 +3,11 @@ MIT License
Copyright for sp_Blitz, sp_BlitzCache, sp_BlitzFirst, sp_BlitzIndex,
sp_BlitzLock, and sp_BlitzWho is held by Brent Ozar Unlimited under MIT licence:
[SQL Server First Responder Kit](https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit)
Copyright for PSBlitz.ps1 is held by Vlad Drumea, 2022 as described below.
Copyright for PSBlitz.ps1, GetStatsInfoForWholeDB.sql, GetOpenTransactions.sql,
GetIndexInfoForWholeDB.sql, GetInstanceInfo.sql, and GetTempDBUsageInfo.sql
is held by Vlad Drumea, 2023 as described below.

Copyright (c) 2023 Vlad Drumea
Copyright (c) 2023 Vlad Drumea - https://vladdba.com/

Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
Expand Down
99 changes: 88 additions & 11 deletions PSBlitz.ps1
Original file line number Diff line number Diff line change
Expand Up @@ -72,8 +72,9 @@
Copyright for sp_Blitz, sp_BlitzCache, sp_BlitzFirst, sp_BlitzIndex,
sp_BlitzLock, and sp_BlitzWho is held by Brent Ozar Unlimited under MIT licence:
SQL Server First Responder Kit - https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit
Copyright for PSBlitz.ps1 is held by Vlad Drumea, 2023 as described below.
Copyright (c) 2023 Vlad Drumea
Copyright for PSBlitz.ps1, GetStatsInfoForWholeDB.sql, GetOpenTransactions.sql,
GetIndexInfoForWholeDB.sql, GetInstanceInfo.sql, and GetTempDBUsageInfo.sql
is held by Vlad Drumea, 2023 as described below.
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
Expand Down Expand Up @@ -222,8 +223,8 @@ param(

###Internal params
#Version
$Vers = "3.3.0"
$VersDate = "20230831"
$Vers = "3.3.1"
$VersDate = "20230927"
#Get script path
$ScriptPath = split-path -parent $MyInvocation.MyCommand.Definition
#Set resources path
Expand Down Expand Up @@ -1104,6 +1105,8 @@ try {
$InstanceInfoTbl = $InstanceInfoSet.Tables[0]
$ResourceInfoTbl = New-Object System.Data.DataTable
$ResourceInfoTbl = $InstanceInfoSet.Tables[1]
$ConnectionsInfoTbl = New-Object System.Data.DataTable
$ConnectionsInfoTbl = $InstanceInfoSet.Tables[2]

if ($ToHTML -eq "Y") {
if ($DebugInfo) {
Expand All @@ -1119,9 +1122,15 @@ try {
@{Name = "Patch Level"; Expression = { $_."patch_level" } },
@{Name = "Edition"; Expression = { $_."edition" } },
@{Name = "Is Clustered?"; Expression = { $_."is_clustered" } },
@{Name = "Is AlwaysOnAG?"; Expression = { $_."always_on_enabled" } },
@{Name = "Is AlwaysOnAG?"; Expression = { $_."always_on_enabled" } },
@{Name = "FILESTREAM Access Level"; Expression = { $_."filestream_access_level" } },
@{Name = "Tempdb Metadata Memory Optimized"; Expression = { $_."mem_optimized_tempdb_metadata" } },
@{Name = "Fulltext Instaled"; Expression = { $_."fulltext_installed" } },
@{Name = "Instance Collation"; Expression = { $_."instance_collation" } },
@{Name = "Process ID"; Expression = { $_."process_id" } },
@{Name = "Last Startup"; Expression = { $_."instance_last_startup" } },
@{Name = "Uptime (days)"; Expression = { $_."uptime_days" } },
@{Name = "Client Connections"; Expression = { $_."client_connections" } },
"Estimated Response Latency (Sec)" | ConvertTo-Html -As Table -Fragment

if ($DebugInfo) {
Expand All @@ -1132,7 +1141,22 @@ try {
@{Name = "Physical memory GB"; Expression = { $_."physical_memory_GB" } },
@{Name = "Max Server Memory GB"; Expression = { $_."max_server_memory_GB" } },
@{Name = "Target Server Memory GB"; Expression = { $_."target_server_memory_GB" } },
@{Name = "Total Memory Used GB"; Expression = { $_."total_memory_used_GB" } } | ConvertTo-Html -As Table -Fragment
@{Name = "Total Memory Used GB"; Expression = { $_."total_memory_used_GB" } },
@{Name = "Process physical memory low"; Expression = { $_."proc_physical_memory_low" } },
@{Name = "Process virtual memory low"; Expression = { $_."proc_virtual_memory_low" } } | ConvertTo-Html -As Table -Fragment

if ($DebugInfo) {
Write-Host " ->Converting connections info to HTML" -fore yellow
}
$htmlTable3 = $ConnectionsInfoTbl | Select-Object "Database",
@{Name = "Connections Count"; Expression = { $_."ConnectionsCount" } },
@{Name = "Login Name"; Expression = { $_."LoginName" } },
@{Name = "Client Hostname"; Expression = { $_."ClientHostName" } },
@{Name = "Client IP"; Expression = { $_."ClientIP" } },
@{Name = "Protocol"; Expression = { $_."ProtocolUsed" } },
@{Name = "Oldest Connection Time"; Expression = { $_."OldestConnectionTime" } },
@{Name = "Program"; Expression = { $_."Program" }} | ConvertTo-Html -As Table -Fragment

$HtmlTabName = "Instance Overview"
$html = $HTMLPre + @"
<title>$HtmlTabName</title>
Expand All @@ -1144,6 +1168,9 @@ $htmlTable1
<b>
<h2 style="text-align: center;">Resource information</h2>
$htmlTable2
<b>
<h2 style="text-align: center;">Top 10 clients by connections</h2>
$htmlTable3
</body>
</html>
"@
Expand All @@ -1165,8 +1192,9 @@ $htmlTable2

#List of columns that should be returned from the data set
$DataSetCols = @("machine_name", "instance_name", "product_version", "product_level",
"patch_level", "edition", "is_clustered", "always_on_enabled", "instance_last_startup",
"uptime_days", "net_latency")
"patch_level", "edition", "is_clustered", "always_on_enabled","filestream_access_level",
"mem_optimized_tempdb_metadata", "fulltext_installed", "instance_collation", "process_id",
"instance_last_startup", "uptime_days", "client_connections", "net_latency")

if ($DebugInfo) {
Write-Host " ->Writing instance info to Excel" -fore yellow
Expand Down Expand Up @@ -1206,7 +1234,7 @@ $htmlTable2

#List of columns that should be returned from the data set
$DataSetCols = @("logical_cpu_cores", "physical_cpu_cores", "physical_memory_GB", "max_server_memory_GB", "target_server_memory_GB",
"total_memory_used_GB")
"total_memory_used_GB", "proc_physical_memory_low", "proc_virtual_memory_low")

if ($DebugInfo) {
Write-Host " ->Writing resource info to Excel" -fore yellow
Expand All @@ -1231,13 +1259,54 @@ $htmlTable2
$ExcelColNum = 1
}

##Top 10 clients by connections section
#Specify at which row in the sheet to start adding the data
$ExcelStartRow = 14
#Specify with which column in the sheet to start
$ExcelColNum = 1
#Set counter used for row retrieval
$RowNum = 0

#List of columns that should be returned from the data set
$DataSetCols = @("Database", "ConnectionsCount", "LoginName", "ClientHostName", "ClientIP", "ProtocolUsed",
"OldestConnectionTime", "Program")

if ($DebugInfo) {
Write-Host " ->Writing Top 10 clients by connections to Excel" -fore yellow
}
#Loop through each Excel row
foreach ($row in $ConnectionsInfoTbl) {
<#
Loop through each data set column of current row and fill the corresponding
Excel cell
#>
foreach ($col in $DataSetCols) {
#Fill Excel cell with value from the data set
if ("OldestConnectionTime" -contains $col) {
$ExcelSheet.Cells.Item($ExcelStartRow, $ExcelColNum) = $ConnectionsInfoTbl.Rows[$RowNum][$col].ToString("yyyy-MM-dd HH:mm:ss")
}
else {
$ExcelSheet.Cells.Item($ExcelStartRow, $ExcelColNum) = $ConnectionsInfoTbl.Rows[$RowNum][$col]
}
$ExcelColNum += 1
}

#move to the next row in the spreadsheet
$ExcelStartRow += 1
#move to the next row in the data set
$RowNum += 1
# reset Excel column number so that next row population begins with column 1
$ExcelColNum = 1
}

##Saving file
$ExcelFile.Save()
}
##Cleaning up variables
Remove-Variable -Name ResourceInfoTbl
Remove-Variable -Name InstanceInfoTbl
Remove-Variable -Name InstanceInfoSet
Remove-Variable -Name ConnectionsInfoTbl
}

if ($JobStatus -ne "Running") {
Expand Down Expand Up @@ -3523,8 +3592,14 @@ $htmlTable
@{Name = "Modifications Count"; Expression = { $_."modification_counter" } },
@{Name = "Modified %"; Expression = { $_."modified_percent" } },
@{Name = "Steps"; Expression = { $_."steps" } },
@{Name = "Incremental"; Expression = { $_."incremental" } },
@{Name = "Temporary"; Expression = { $_."temporary" } },
@{Name = "With NORECOMPUTE"; Expression = { $_."no_recompute"} },
@{Name = "Persisted Sample"; Expression = { $_."persisted_sample"} },
@{Name = "Persisted Sample %"; Expression = { $_."persisted_sample_percent"} },
@{Name = "Partitioned"; Expression = { $_."partitioned" } },
@{Name = "Partition No."; Expression = { $_."partition_number" } } | ConvertTo-Html -As Table -Fragment
@{Name = "Partition No."; Expression = { $_."partition_number" } },
@{Name = "Get Stats Details"; Expression = { $_."get_details" } } | ConvertTo-Html -As Table -Fragment
$HtmlTabName = "Statistics info for $CheckDB"
$html = $HTMLPre + @"
<title>$HtmlTabName</title>
Expand All @@ -3550,7 +3625,9 @@ $htmlTable
$DataSetCols = @("database", "object_name", "object_type", "stats_name", "origin",
"filter_definition", "last_updated", "rows", "unfiltered_rows",
"rows_sampled", "sample_percent", "modification_counter",
"modified_percent", "steps", "partitioned", "partition_number")
"modified_percent", "incremental", "temporary", "no_recompute", "persisted_sample",
"persisted_sample_percent", "steps", "partitioned", "partition_number",
"get_details")

if ($DebugInfo) {
Write-Host " ->Writing Stats results to sheet Statistics Info" -fore yellow
Expand Down
84 changes: 70 additions & 14 deletions Resources/GetInstanceInfo.sql
Original file line number Diff line number Diff line change
@@ -1,11 +1,16 @@
/*
Part of PSBlitz - https://github.com/VladDBA/PSBlitz
License - https://github.com/VladDBA/PSBlitz/blob/main/LICENSE
*/
SET NOCOUNT ON;
SET STATISTICS XML OFF;
SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
/*Get instance info*/
SELECT SERVERPROPERTY('MachineName') AS [machine_name],
ISNULL(CAST(SERVERPROPERTY('InstanceName') AS NVARCHAR(100)), '(default instance)') AS [instance_name],
SERVERPROPERTY('ProductVersion') AS [product_version],
SERVERPROPERTY('ProductLevel') AS [product_level],
SERVERPROPERTY('ProductUpdateLevel') AS [patch_level],
SERVERPROPERTY('ProductUpdateLevel') AS [patch_level],
SERVERPROPERTY('Edition') AS [edition],
CASE
WHEN SERVERPROPERTY('IsClustered') = 1 THEN 'Yes'
Expand All @@ -17,9 +22,31 @@ SELECT SERVERPROPERTY('MachineName')
WHEN SERVERPROPERTY('IsHadrEnabled') = 0 THEN 'No'
ELSE 'N/A'
END AS [always_on_enabled],
CASE
WHEN SERVERPROPERTY('FilestreamConfiguredLevel') = 0 THEN '0 - Disabled'
WHEN SERVERPROPERTY('FilestreamConfiguredLevel') = 1 THEN '1 - T-SQL'
WHEN SERVERPROPERTY('FilestreamConfiguredLevel') = 2 THEN '2 - T-SQL & local streaming'
WHEN SERVERPROPERTY('FilestreamConfiguredLevel') = 3 THEN '3 - T-SQL & remote streaming'
ELSE 'N/A'
END AS [filestream_access_level],
CASE
WHEN SERVERPROPERTY('IsTempdbMetadataMemoryOptimized') = 1 THEN 'Yes'
WHEN SERVERPROPERTY('IsTempdbMetadataMemoryOptimized') = 0 THEN 'No'
ELSE 'N/A'
END AS [mem_optimized_tempdb_metadata],
CASE
WHEN SERVERPROPERTY('IsFullTextInstalled') = 1 THEN 'Yes'
WHEN SERVERPROPERTY('IsFullTextInstalled') = 0 THEN 'No'
ELSE 'N/A'
END AS [fulltext_installed],
SERVERPROPERTY('Collation') AS [instance_collation],
[sqlserver_start_time] AS [instance_last_startup],
CAST(DATEDIFF(HH, [sqlserver_start_time], GETDATE()) / 24.00 AS NUMERIC(23, 2)) AS [uptime_days]
FROM [sys].[dm_os_sys_info];
SERVERPROPERTY('ProcessID') AS [process_id],
CAST(DATEDIFF(HH, [sqlserver_start_time], GETDATE()) / 24.00 AS NUMERIC(23, 2)) AS [uptime_days],
(SELECT COUNT(*)
FROM [sys].[dm_exec_connections]) AS [client_connections]
FROM [sys].[dm_os_sys_info]
OPTION(RECOMPILE);


/*Get resource info*/
Expand All @@ -37,21 +64,50 @@ SELECT @SQL = N'SELECT [cpu_count] AS [logical_cpu_cores],'
THEN N'''-- N/A --'''
ELSE N'( [socket_count] * [cores_per_socket] )'
END +N' AS [physical_cpu_cores],'
+ @LineFeed + N'CAST(ROUND(( [physical_memory_kb] / 1024.0 / 1024 ), 1) AS INT) AS [physical_memory_GB],'
+ @LineFeed + N'(SELECT CAST(CAST([value_in_use] AS INT) / 1024.0 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[configurations]'
+ @LineFeed + N'WHERE [name] = N''max server memory (MB)'') AS [max_server_memory_GB],'
+ @LineFeed + N'(SELECT TOP(1) CAST([cntr_value] / 1024.0 / 1024 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[dm_os_performance_counters]'
+ @LineFeed + N'CAST(ROUND(( [physical_memory_kb] / 1024.00 / 1024.00 ), 1) AS DECIMAL(15, 2)) AS [physical_memory_GB],'
+ @LineFeed + N'(SELECT CAST(CAST([value_in_use] AS INT) / 1024.00 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[configurations]'
+ @LineFeed + N'WHERE [name] = N''max server memory (MB)'') AS [max_server_memory_GB],'
+ @LineFeed + N'(SELECT TOP(1) CAST([cntr_value] / 1024.00 / 1024.00 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[dm_os_performance_counters]'
+ @LineFeed + N'WHERE [object_name] LIKE N''%Memory Manager%'''
+ @LineFeed + N'AND [counter_name] LIKE N''Target Server Memory (KB)%'''
+ @LineFeed + N'ORDER BY [cntr_value] DESC) AS [target_server_memory_GB],'
+ @LineFeed + N'(SELECT TOP(1) CAST([cntr_value] / 1024.0 / 1024 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[dm_os_performance_counters]'
+ @LineFeed + N'(SELECT TOP(1) CAST([cntr_value] / 1024.00 / 1024.00 AS DECIMAL(15, 2))'
+ @LineFeed + N'FROM [sys].[dm_os_performance_counters]'
+ @LineFeed + N'WHERE [object_name] LIKE N''%Memory Manager%'''
+ @LineFeed + N'AND [counter_name] LIKE N''Total Server Memory (KB)%'') AS [total_memory_used_GB]'
+ @LineFeed + N'FROM [sys].[dm_os_sys_info];'
+ @LineFeed + N'AND [counter_name] LIKE N''Total Server Memory (KB)%'') AS [total_memory_used_GB],'
+ @LineFeed + N'(SELECT CASE WHEN [process_physical_memory_low] = 1 THEN ''Yes'''
+ @LineFeed + N'ELSE ''No'' END FROM sys.dm_os_process_memory) AS [proc_physical_memory_low],'
+ @LineFeed + N'(SELECT CASE WHEN [process_virtual_memory_low] = 1 THEN ''Yes'''
+ @LineFeed + N'ELSE ''No'' END FROM sys.dm_os_process_memory) AS [proc_virtual_memory_low]'
+ @LineFeed + N'FROM [sys].[dm_os_sys_info] OPTION(RECOMPILE);'

BEGIN
EXEC(@SQL);
EXEC(@SQL);
END;

/*Get connection info*/
SELECT TOP 10 [d].[name] AS [Database],
COUNT([s].[status]) AS [ConnectionsCount],
RTRIM(LTRIM([s].[login_name])) AS [LoginName],
ISNULL([s].[host_name], N'N/A') AS [ClientHostName],
REPLACE(REPLACE([c].[client_net_address], N'<', N''), N'>', N'') AS [ClientIP],
[c].[net_transport] AS [ProtocolUsed],
MAX([c].[connect_time]) AS [OldestConnectionTime],
[s].[program_name] AS [Program]
FROM sys.dm_exec_sessions AS [s]
LEFT JOIN sys.databases AS [d]
ON [d].[database_id] = [s].[database_id]
INNER JOIN sys.dm_exec_connections AS [c]
ON [s].[session_id] = [c].[session_id]
GROUP BY [d].[database_id],
[d].[name],
[s].[login_name],
[s].[security_id],
[s].[host_name],
[c].[client_net_address],
[c].[net_transport],
[s].[program_name]
ORDER BY [ConnectionsCount] DESC
OPTION(RECOMPILE);
Loading

0 comments on commit 745f017

Please sign in to comment.