forked from BrentOzarULTD/SQL-Server-First-Responder-Kit
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsp_foreachdb.sql
286 lines (251 loc) · 11.3 KB
/
sp_foreachdb.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
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
IF OBJECT_ID('dbo.sp_foreachdb') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_foreachdb AS RETURN 0');
GO
ALTER PROCEDURE dbo.sp_foreachdb
-- Original fields from sp_MSforeachdb...
@command1 NVARCHAR(MAX) = NULL,
@replacechar NCHAR(1) = N'?' ,
@command2 NVARCHAR(MAX) = NULL ,
@command3 NVARCHAR(MAX) = NULL ,
@precommand NVARCHAR(MAX) = NULL ,
@postcommand NVARCHAR(MAX) = NULL ,
-- Additional fields for our sp_foreachdb!
@command NVARCHAR(MAX) = NULL, --For backwards compatibility
@print_dbname BIT = 0 ,
@print_command_only BIT = 0 ,
@suppress_quotename BIT = 0 ,
@system_only BIT = NULL ,
@user_only BIT = NULL ,
@name_pattern NVARCHAR(300) = N'%' ,
@database_list NVARCHAR(MAX) = NULL ,
@exclude_list NVARCHAR(MAX) = NULL ,
@recovery_model_desc NVARCHAR(120) = NULL ,
@compatibility_level TINYINT = NULL ,
@state_desc NVARCHAR(120) = N'ONLINE' ,
@is_read_only BIT = 0 ,
@is_auto_close_on BIT = NULL ,
@is_auto_shrink_on BIT = NULL ,
@is_broker_enabled BIT = NULL ,
@Help BIT = 0,
@Version VARCHAR(30) = NULL OUTPUT,
@VersionDate DATETIME = NULL OUTPUT,
@VersionCheckMode BIT = 0
AS
BEGIN
SET NOCOUNT ON;
SELECT @Version = '3.5', @VersionDate = '20190427';
IF(@VersionCheckMode = 1)
BEGIN
RETURN;
END;
IF @Help = 1
BEGIN
PRINT '
/*
sp_foreachdb from http://FirstResponderKit.org
This script will execute a given command against all, or user-specified,
online, readable databases on an instance.
To learn more, visit http://FirstResponderKit.org where you can download new
versions for free, watch training videos on how it works, get more info on
the findings, contribute your own code, and more.
Known limitations of this version:
- Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000.
- Tastes awful with marmite.
Unknown limitations of this version:
- None. (If we knew them, they would be known. Duh.)
Changes - for the full list of improvements and fixes in this version, see:
https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/
MIT License
Copyright (c) 2019 Brent Ozar Unlimited
Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.
Example for basic execution of the stored procedure:
exec dbo.sp_foreachdb
@command = ''select [name] sys.tables''
,@database_list = ''Database1,Database2''
,@exclude_list = ''Database5,OldDatabase'';
*/
';
RETURN -1;
END
IF ( (@command1 IS NOT NULL AND @command IS NOT NULL)
OR (@command1 IS NULL AND @command IS NULL) )
BEGIN
RAISERROR('You must supply either @command1 or @command, but not both.',16,1);
RETURN -1;
END;
SET @command1 = COALESCE(@command1,@command);
DECLARE @sql NVARCHAR(MAX) ,
@dblist NVARCHAR(MAX) ,
@exlist NVARCHAR(MAX) ,
@db NVARCHAR(300) ,
@i INT;
IF @database_list > N''
BEGIN
;
WITH n ( n )
AS ( SELECT ROW_NUMBER() OVER ( ORDER BY s1.name )
- 1
FROM sys.objects AS s1
CROSS JOIN sys.objects AS s2
)
SELECT @dblist = REPLACE(REPLACE(REPLACE(x, '</x><x>',
','), '</x>', ''),
'<x>', '')
FROM ( SELECT DISTINCT
x = 'N'''
+ LTRIM(RTRIM(SUBSTRING(@database_list,
n,
CHARINDEX(',',
@database_list
+ ',', n) - n)))
+ ''''
FROM n
WHERE n <= LEN(@database_list)
AND SUBSTRING(',' + @database_list, n,
1) = ','
FOR
XML PATH('')
) AS y ( x );
END
-- Added for @exclude_list
IF @exclude_list > N''
BEGIN
;
WITH n ( n )
AS ( SELECT ROW_NUMBER() OVER ( ORDER BY s1.name )
- 1
FROM sys.objects AS s1
CROSS JOIN sys.objects AS s2
)
SELECT @exlist = REPLACE(REPLACE(REPLACE(x, '</x><x>',
','), '</x>', ''),
'<x>', '')
FROM ( SELECT DISTINCT
x = 'N'''
+ LTRIM(RTRIM(SUBSTRING(@exclude_list,
n,
CHARINDEX(',',
@exclude_list
+ ',', n) - n)))
+ ''''
FROM n
WHERE n <= LEN(@exclude_list)
AND SUBSTRING(',' + @exclude_list, n,
1) = ','
FOR
XML PATH('')
) AS y ( x );
END
CREATE TABLE #x ( db NVARCHAR(300) );
SET @sql = N'SELECT name FROM sys.databases d WHERE 1=1'
+ CASE WHEN @system_only = 1 THEN ' AND d.database_id IN (1,2,3,4)'
ELSE ''
END
+ CASE WHEN @user_only = 1
THEN ' AND d.database_id NOT IN (1,2,3,4)'
ELSE ''
END
-- To exclude databases from changes
+ CASE WHEN @exlist IS NOT NULL
THEN ' AND d.name NOT IN (' + @exlist + ')'
ELSE ''
END + CASE WHEN @name_pattern <> N'%'
THEN ' AND d.name LIKE N''' + REPLACE(@name_pattern,
'''', '''''')
+ ''''
ELSE ''
END + CASE WHEN @dblist IS NOT NULL
THEN ' AND d.name IN (' + @dblist + ')'
ELSE ''
END
+ CASE WHEN @recovery_model_desc IS NOT NULL
THEN ' AND d.recovery_model_desc = N'''
+ @recovery_model_desc + ''''
ELSE ''
END
+ CASE WHEN @compatibility_level IS NOT NULL
THEN ' AND d.compatibility_level = '
+ RTRIM(@compatibility_level)
ELSE ''
END
+ CASE WHEN @state_desc IS NOT NULL
THEN ' AND d.state_desc = N''' + @state_desc + ''''
ELSE ''
END
+ CASE WHEN @state_desc = 'ONLINE' AND SERVERPROPERTY('IsHadrEnabled') = 1
THEN ' AND NOT EXISTS (SELECT 1
FROM sys.dm_hadr_database_replica_states drs
JOIN sys.availability_replicas ar
ON ar.replica_id = drs.replica_id
JOIN sys.dm_hadr_availability_group_states ags
ON ags.group_id = ar.group_id
WHERE drs.database_id = d.database_id
AND ar.secondary_role_allow_connections = 0
AND ags.primary_replica <> @@SERVERNAME)'
ELSE ''
END
+ CASE WHEN @is_read_only IS NOT NULL
THEN ' AND d.is_read_only = ' + RTRIM(@is_read_only)
ELSE ''
END
+ CASE WHEN @is_auto_close_on IS NOT NULL
THEN ' AND d.is_auto_close_on = ' + RTRIM(@is_auto_close_on)
ELSE ''
END
+ CASE WHEN @is_auto_shrink_on IS NOT NULL
THEN ' AND d.is_auto_shrink_on = ' + RTRIM(@is_auto_shrink_on)
ELSE ''
END
+ CASE WHEN @is_broker_enabled IS NOT NULL
THEN ' AND d.is_broker_enabled = ' + RTRIM(@is_broker_enabled)
ELSE ''
END;
INSERT #x
EXEC sp_executesql @sql;
DECLARE c CURSOR LOCAL FORWARD_ONLY STATIC READ_ONLY
FOR
SELECT CASE WHEN @suppress_quotename = 1 THEN db
ELSE QUOTENAME(db)
END
FROM #x
ORDER BY db;
OPEN c;
FETCH NEXT FROM c INTO @db;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @sql = REPLACE(@command1, @replacechar, @db);
IF @suppress_quotename = 0 SET @sql = REPLACE(REPLACE(@sql,'[[','['),']]',']');
IF @print_command_only = 1
BEGIN
PRINT '/* For ' + @db + ': */' + CHAR(13) + CHAR(10)
+ CHAR(13) + CHAR(10) + @sql + CHAR(13) + CHAR(10)
+ CHAR(13) + CHAR(10);
END
ELSE
BEGIN
IF @print_dbname = 1
BEGIN
PRINT '/* ' + @db + ' */';
END
EXEC sp_executesql @sql;
END
FETCH NEXT FROM c INTO @db;
END
CLOSE c;
DEALLOCATE c;
END
GO