-
Notifications
You must be signed in to change notification settings - Fork 21
/
Copy pathGetInstanceInfo.sql
242 lines (234 loc) · 13.5 KB
/
GetInstanceInfo.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
/*
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 ISNULL(SERVERPROPERTY('MachineName'),'N/A') 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],
CASE
WHEN CAST(SERVERPROPERTY('EngineEdition') AS INT) = 8 THEN 'Azure SQL Managed Instance'
ELSE SERVERPROPERTY('Edition')
END AS [edition],
CASE
WHEN SERVERPROPERTY('IsClustered') = 1 THEN 'Yes'
WHEN SERVERPROPERTY('IsClustered') = 0 THEN 'No'
ELSE 'N/A'
END AS [is_clustered],
CASE
WHEN SERVERPROPERTY('IsHadrEnabled') = 1 THEN 'Yes'
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 [tempdb_metadata_memory_optimized],
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],
(SELECT COUNT([database_id]) FROM [sys].[databases] WHERE [database_id] > 4) AS [user_db_count],
CONVERT(VARCHAR(22),[sqlserver_start_time],120) AS [instance_last_startup],
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],
CAST(0 AS DECIMAL(6,3)) AS [estimated_response_latency(sec)],
CONVERT(VARCHAR(30),SYSDATETIMEOFFSET(),120) AS [server_time]
FROM [sys].[dm_os_sys_info]
OPTION(RECOMPILE);
/*Get resource info*/
DECLARE @SQL NVARCHAR(MAX);
DECLARE @LineFeed NVARCHAR(5);
SET @LineFeed = CHAR(13) + CHAR(10);
SELECT @SQL = CASE
/*Skipping this query on Azure SQL DB*/
WHEN CAST(SERVERPROPERTY('Edition') AS NVARCHAR(100)) = N'SQL Azure'
AND SERVERPROPERTY('EngineEdition') IN ( 5, 6 ) THEN CAST(N'SELECT ''Not available'' AS [logical_cpu_cores], '' in Azure '' AS [physical_CPU_cores], ''SQL DB'' ' AS NVARCHAR(MAX))
+ N'[AS physical_memory_GB], NULL AS [max_server_memory_GB], NULL AS [target_server_memory_GB], '
+ N'NULL AS [total_memory_used_GB], NULL AS [proc_physical_memory_low], NULL AS [proc_virtual_memory_low], '
+ N'NULL AS [available_physical_memory_GB], NULL AS [os_memory_state], NULL AS [CTP], NULL AS [MAXDOP]'
ELSE CAST(N'SELECT [cpu_count] AS [logical_cpu_cores],' AS NVARCHAR(MAX))
+ @LineFeed
+ CASE
WHEN /*If running on SQL Server 2016 SP1 or lower, don't retrieve physical_cpu_cores*/
( CAST(SERVERPROPERTY('ProductMajorVersion') AS TINYINT) = 13
AND CAST(SERVERPROPERTY('ProductLevel') AS NVARCHAR(128)) IN ( N'RTM', N'SP1' ) )
OR CAST(ISNULL(SERVERPROPERTY('ProductMajorVersion'),0) AS TINYINT) < 13 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.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.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'(SELECT CAST(COUNT(*) * 8/1024.0/1024.0 AS DECIMAL (15,2))'
+ @LineFeed
+ N' FROM sys.dm_os_buffer_descriptors WHERE database_id <> 32767) AS [buffer_pool_usage_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 [process_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 [process_virtual_memory_low],'
+ @LineFeed
+ N'(SELECT CAST(([available_physical_memory_kb]/1024.00/1024.00) AS DECIMAL(15, 2))'
+ @LineFeed
+ N' FROM [sys].[dm_os_sys_memory]) AS [available_physical_memory_GB],'
+ @LineFeed
+ N'(SELECT [system_memory_state_desc] FROM [sys].[dm_os_sys_memory]) AS [OS_memory_state],'
+ @LineFeed
+ N'(SELECT [value] FROM [sys].[configurations]'
+ @LineFeed
+ N' WHERE [name] = N''cost threshold for parallelism'') AS [CTP],'
+ @LineFeed
+ N'(SELECT [value] FROM [sys].[configurations]'
+ @LineFeed
+ N' WHERE [name] = N''max degree of parallelism'') AS [MAXDOP]'
+ @LineFeed
+ N'FROM [sys].[dm_os_sys_info] OPTION(RECOMPILE);'
END;
BEGIN
EXEC(@SQL);
END;
/*Get connection info*/
SELECT TOP 10 [d].[name] AS [database],
COUNT([s].[status]) AS [connections_count],
RTRIM(LTRIM([s].[login_name])) AS [login_name],
ISNULL([s].[host_name], N'N/A') AS [client_host_name],
REPLACE(REPLACE([c].[client_net_address], N'<', N''), N'>', N'') AS [client_IP],
[c].[net_transport] AS [Protocol],
CONVERT(VARCHAR(25),MAX([c].[connect_time]),121) AS [oldest_connection_time],
[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 [connections_count] DESC
OPTION(RECOMPILE);
/*Get SET options from both session and instance*/
DECLARE @InstanceLevelOption INT;
SELECT @InstanceLevelOption = CAST([value_in_use] AS INT)
FROM sys.configurations
WHERE [name] = N'user options';
;
WITH OPTCTE
AS (SELECT Options.[id],
Options.[Option],
Options.[Description],
ROW_NUMBER()
OVER (
PARTITION BY 1
ORDER BY id) AS [bitNum]
FROM (VALUES (1,
'DISABLE_DEF_CNST_CHK',
'Controls interim or deferred constraint checking. - obsolete and should not be on!'),
(2,
'IMPLICIT_TRANSACTIONS',
'Controls whether a transaction is started implicitly when a statement is executed.'),
(4,
'CURSOR_CLOSE_ON_COMMIT',
'Controls behavior of cursors after a commit operation has been performed.'),
(8,
'ANSI_WARNINGS',
'Controls truncation and NULL in aggregate warnings.'),
(16,
'ANSI_PADDING',
'Controls padding of fixed-length variables.'),
(32,
'ANSI_NULLS',
'Controls NULL handling when using equality operators.'),
(64,
'ARITHABORT',
'Terminates a query when an overflow or divide-by-zero error occurs during query execution.'),
(128,
'ARITHIGNORE',
'Returns NULL when an overflow or divide-by-zero error occurs during a query.'),
(256,
'QUOTED_IDENTIFIER',
'Differentiates between single and double quotation marks when evaluating an expression.'),
(512,
'NOCOUNT',
'Turns off the message returned at the end of each statement that states how many rows were affected.'),
(1024,
'ANSI_NULL_DFLT_ON',
'Alters the session''s behavior to use ANSI compatibility for nullability. New columns defined without explicit nullability are defined to allow nulls.'),
(2048,
'ANSI_NULL_DFLT_OFF',
'Alters the session''s behavior not to use ANSI compatibility for nullability. New columns defined without explicit nullability do not allow nulls.'),
(4096,
'CONCAT_NULL_YIELDS_NULL',
'Returns NULL when concatenating a NULL value with a string.'),
(8192,
'NUMERIC_ROUNDABORT',
'Generates an error when a loss of precision occurs in an expression.'),
(16384,
'XACT_ABORT',
'Rolls back a transaction if a Transact-SQL statement raises a run-time error.') ) AS Options([id], [Option], [Description]))
SELECT [Option],
CASE
WHEN ( @@OPTIONS & id ) = id THEN 'ON'
ELSE 'OFF'
END AS [Session_Setting],
CASE
WHEN ( @InstanceLevelOption & id ) = id THEN 'ON'
ELSE 'OFF'
END AS [Instance_Setting],
[Description],
CASE
WHEN [Description] LIKE '%obsolete%' THEN ''
ELSE 'https://learn.microsoft.com/en-us/sql/t-sql/statements/set-'
+ LOWER(REPLACE([Option], '_', '-'))
+ '-transact-sql'
END AS [URL]
FROM OPTCTE
ORDER BY [Option]
OPTION(RECOMPILE);