|
| 1 | +IF OBJECT_ID('dbo.sp_foreachdb') IS NULL |
| 2 | + EXEC ('CREATE PROCEDURE dbo.sp_foreachdb AS RETURN 0'); |
| 3 | +GO |
| 4 | + |
| 5 | +ALTER PROCEDURE dbo.sp_foreachdb |
| 6 | + -- Original fields from sp_MSforeachdb... |
| 7 | + @command1 NVARCHAR(MAX) = NULL, |
| 8 | + @replacechar NCHAR(1) = N'?' , |
| 9 | + @command2 NVARCHAR(MAX) = NULL , |
| 10 | + @command3 NVARCHAR(MAX) = NULL , |
| 11 | + @precommand NVARCHAR(MAX) = NULL , |
| 12 | + @postcommand NVARCHAR(MAX) = NULL , |
| 13 | + -- Additional fields for our sp_foreachdb! |
| 14 | + @command NVARCHAR(MAX) = NULL, --For backwards compatibility |
| 15 | + @print_dbname BIT = 0 , |
| 16 | + @print_command_only BIT = 0 , |
| 17 | + @suppress_quotename BIT = 0 , |
| 18 | + @system_only BIT = NULL , |
| 19 | + @user_only BIT = NULL , |
| 20 | + @name_pattern NVARCHAR(300) = N'%' , |
| 21 | + @database_list NVARCHAR(MAX) = NULL , |
| 22 | + @exclude_list NVARCHAR(MAX) = NULL , |
| 23 | + @recovery_model_desc NVARCHAR(120) = NULL , |
| 24 | + @compatibility_level TINYINT = NULL , |
| 25 | + @state_desc NVARCHAR(120) = N'ONLINE' , |
| 26 | + @is_read_only BIT = 0 , |
| 27 | + @is_auto_close_on BIT = NULL , |
| 28 | + @is_auto_shrink_on BIT = NULL , |
| 29 | + @is_broker_enabled BIT = NULL , |
| 30 | + @Help BIT = 0, |
| 31 | + @Version VARCHAR(30) = NULL OUTPUT, |
| 32 | + @VersionDate DATETIME = NULL OUTPUT, |
| 33 | + @VersionCheckMode BIT = 0 |
| 34 | +AS |
| 35 | + BEGIN |
| 36 | + SET NOCOUNT ON; |
| 37 | + SELECT @Version = '3.7', @VersionDate = '20190826'; |
| 38 | + |
| 39 | +IF(@VersionCheckMode = 1) |
| 40 | +BEGIN |
| 41 | + RETURN; |
| 42 | +END; |
| 43 | + |
| 44 | + |
| 45 | +IF @Help = 1 |
| 46 | + |
| 47 | + BEGIN |
| 48 | + |
| 49 | + PRINT ' |
| 50 | + /* |
| 51 | + sp_foreachdb from http://FirstResponderKit.org |
| 52 | + |
| 53 | + This script will execute a given command against all, or user-specified, |
| 54 | + online, readable databases on an instance. |
| 55 | + |
| 56 | + To learn more, visit http://FirstResponderKit.org where you can download new |
| 57 | + versions for free, watch training videos on how it works, get more info on |
| 58 | + the findings, contribute your own code, and more. |
| 59 | + |
| 60 | + Known limitations of this version: |
| 61 | + - Only Microsoft-supported versions of SQL Server. Sorry, 2005 and 2000. |
| 62 | + - Tastes awful with marmite. |
| 63 | + |
| 64 | + Unknown limitations of this version: |
| 65 | + - None. (If we knew them, they would be known. Duh.) |
| 66 | + |
| 67 | + Changes - for the full list of improvements and fixes in this version, see: |
| 68 | + https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/ |
| 69 | + |
| 70 | + MIT License |
| 71 | + |
| 72 | + Copyright (c) 2019 Brent Ozar Unlimited |
| 73 | + |
| 74 | + Permission is hereby granted, free of charge, to any person obtaining a copy |
| 75 | + of this software and associated documentation files (the "Software"), to deal |
| 76 | + in the Software without restriction, including without limitation the rights |
| 77 | + to use, copy, modify, merge, publish, distribute, sublicense, and/or sell |
| 78 | + copies of the Software, and to permit persons to whom the Software is |
| 79 | + furnished to do so, subject to the following conditions: |
| 80 | + |
| 81 | + The above copyright notice and this permission notice shall be included in all |
| 82 | + copies or substantial portions of the Software. |
| 83 | + |
| 84 | + THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR |
| 85 | + IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, |
| 86 | + FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE |
| 87 | + AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER |
| 88 | + LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, |
| 89 | + OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE |
| 90 | + SOFTWARE. |
| 91 | + |
| 92 | + Example for basic execution of the stored procedure: |
| 93 | + |
| 94 | + exec dbo.sp_foreachdb |
| 95 | + @command = ''select [name] sys.tables'' |
| 96 | + ,@database_list = ''Database1,Database2'' |
| 97 | + ,@exclude_list = ''Database5,OldDatabase''; |
| 98 | + |
| 99 | + */ |
| 100 | + '; |
| 101 | + RETURN -1; |
| 102 | + END |
| 103 | + |
| 104 | + IF ( (@command1 IS NOT NULL AND @command IS NOT NULL) |
| 105 | + OR (@command1 IS NULL AND @command IS NULL) ) |
| 106 | + BEGIN |
| 107 | + RAISERROR('You must supply either @command1 or @command, but not both.',16,1); |
| 108 | + RETURN -1; |
| 109 | + END; |
| 110 | + |
| 111 | + SET @command1 = COALESCE(@command1,@command); |
| 112 | + |
| 113 | + DECLARE @sql NVARCHAR(MAX) , |
| 114 | + @dblist NVARCHAR(MAX) , |
| 115 | + @exlist NVARCHAR(MAX) , |
| 116 | + @db NVARCHAR(300) , |
| 117 | + @i INT; |
| 118 | + |
| 119 | + IF @database_list > N'' |
| 120 | + BEGIN |
| 121 | + ; |
| 122 | + WITH n ( n ) |
| 123 | + AS ( SELECT ROW_NUMBER() OVER ( ORDER BY s1.name ) |
| 124 | + - 1 |
| 125 | + FROM sys.objects AS s1 |
| 126 | + CROSS JOIN sys.objects AS s2 |
| 127 | + ) |
| 128 | + SELECT @dblist = REPLACE(REPLACE(REPLACE(x, '</x><x>', |
| 129 | + ','), '</x>', ''), |
| 130 | + '<x>', '') |
| 131 | + FROM ( SELECT DISTINCT |
| 132 | + x = 'N''' |
| 133 | + + LTRIM(RTRIM(SUBSTRING(@database_list, |
| 134 | + n, |
| 135 | + CHARINDEX(',', |
| 136 | + @database_list |
| 137 | + + ',', n) - n))) |
| 138 | + + '''' |
| 139 | + FROM n |
| 140 | + WHERE n <= LEN(@database_list) |
| 141 | + AND SUBSTRING(',' + @database_list, n, |
| 142 | + 1) = ',' |
| 143 | + FOR |
| 144 | + XML PATH('') |
| 145 | + ) AS y ( x ); |
| 146 | + END |
| 147 | +-- Added for @exclude_list |
| 148 | + IF @exclude_list > N'' |
| 149 | + BEGIN |
| 150 | + ; |
| 151 | + WITH n ( n ) |
| 152 | + AS ( SELECT ROW_NUMBER() OVER ( ORDER BY s1.name ) |
| 153 | + - 1 |
| 154 | + FROM sys.objects AS s1 |
| 155 | + CROSS JOIN sys.objects AS s2 |
| 156 | + ) |
| 157 | + SELECT @exlist = REPLACE(REPLACE(REPLACE(x, '</x><x>', |
| 158 | + ','), '</x>', ''), |
| 159 | + '<x>', '') |
| 160 | + FROM ( SELECT DISTINCT |
| 161 | + x = 'N''' |
| 162 | + + LTRIM(RTRIM(SUBSTRING(@exclude_list, |
| 163 | + n, |
| 164 | + CHARINDEX(',', |
| 165 | + @exclude_list |
| 166 | + + ',', n) - n))) |
| 167 | + + '''' |
| 168 | + FROM n |
| 169 | + WHERE n <= LEN(@exclude_list) |
| 170 | + AND SUBSTRING(',' + @exclude_list, n, |
| 171 | + 1) = ',' |
| 172 | + FOR |
| 173 | + XML PATH('') |
| 174 | + ) AS y ( x ); |
| 175 | + END |
| 176 | + |
| 177 | + CREATE TABLE #x ( db NVARCHAR(300) ); |
| 178 | + |
| 179 | + SET @sql = N'SELECT name FROM sys.databases d WHERE 1=1' |
| 180 | + + CASE WHEN @system_only = 1 THEN ' AND d.database_id IN (1,2,3,4)' |
| 181 | + ELSE '' |
| 182 | + END |
| 183 | + + CASE WHEN @user_only = 1 |
| 184 | + THEN ' AND d.database_id NOT IN (1,2,3,4)' |
| 185 | + ELSE '' |
| 186 | + END |
| 187 | +-- To exclude databases from changes |
| 188 | + + CASE WHEN @exlist IS NOT NULL |
| 189 | + THEN ' AND d.name NOT IN (' + @exlist + ')' |
| 190 | + ELSE '' |
| 191 | + END + CASE WHEN @name_pattern <> N'%' |
| 192 | + THEN ' AND d.name LIKE N''' + REPLACE(@name_pattern, |
| 193 | + '''', '''''') |
| 194 | + + '''' |
| 195 | + ELSE '' |
| 196 | + END + CASE WHEN @dblist IS NOT NULL |
| 197 | + THEN ' AND d.name IN (' + @dblist + ')' |
| 198 | + ELSE '' |
| 199 | + END |
| 200 | + + CASE WHEN @recovery_model_desc IS NOT NULL |
| 201 | + THEN ' AND d.recovery_model_desc = N''' |
| 202 | + + @recovery_model_desc + '''' |
| 203 | + ELSE '' |
| 204 | + END |
| 205 | + + CASE WHEN @compatibility_level IS NOT NULL |
| 206 | + THEN ' AND d.compatibility_level = ' |
| 207 | + + RTRIM(@compatibility_level) |
| 208 | + ELSE '' |
| 209 | + END |
| 210 | + + CASE WHEN @state_desc IS NOT NULL |
| 211 | + THEN ' AND d.state_desc = N''' + @state_desc + '''' |
| 212 | + ELSE '' |
| 213 | + END |
| 214 | + + CASE WHEN @state_desc = 'ONLINE' AND SERVERPROPERTY('IsHadrEnabled') = 1 |
| 215 | + THEN ' AND NOT EXISTS (SELECT 1 |
| 216 | + FROM sys.dm_hadr_database_replica_states drs |
| 217 | + JOIN sys.availability_replicas ar |
| 218 | + ON ar.replica_id = drs.replica_id |
| 219 | + JOIN sys.dm_hadr_availability_group_states ags |
| 220 | + ON ags.group_id = ar.group_id |
| 221 | + WHERE drs.database_id = d.database_id |
| 222 | + AND ar.secondary_role_allow_connections = 0 |
| 223 | + AND ags.primary_replica <> @@SERVERNAME)' |
| 224 | + ELSE '' |
| 225 | + END |
| 226 | + + CASE WHEN @is_read_only IS NOT NULL |
| 227 | + THEN ' AND d.is_read_only = ' + RTRIM(@is_read_only) |
| 228 | + ELSE '' |
| 229 | + END |
| 230 | + + CASE WHEN @is_auto_close_on IS NOT NULL |
| 231 | + THEN ' AND d.is_auto_close_on = ' + RTRIM(@is_auto_close_on) |
| 232 | + ELSE '' |
| 233 | + END |
| 234 | + + CASE WHEN @is_auto_shrink_on IS NOT NULL |
| 235 | + THEN ' AND d.is_auto_shrink_on = ' + RTRIM(@is_auto_shrink_on) |
| 236 | + ELSE '' |
| 237 | + END |
| 238 | + + CASE WHEN @is_broker_enabled IS NOT NULL |
| 239 | + THEN ' AND d.is_broker_enabled = ' + RTRIM(@is_broker_enabled) |
| 240 | + ELSE '' |
| 241 | + END; |
| 242 | + |
| 243 | + INSERT #x |
| 244 | + EXEC sp_executesql @sql; |
| 245 | + |
| 246 | + DECLARE c CURSOR LOCAL FORWARD_ONLY STATIC READ_ONLY |
| 247 | + FOR |
| 248 | + SELECT CASE WHEN @suppress_quotename = 1 THEN db |
| 249 | + ELSE QUOTENAME(db) |
| 250 | + END |
| 251 | + FROM #x |
| 252 | + ORDER BY db; |
| 253 | + |
| 254 | + OPEN c; |
| 255 | + |
| 256 | + FETCH NEXT FROM c INTO @db; |
| 257 | + |
| 258 | + WHILE @@FETCH_STATUS = 0 |
| 259 | + BEGIN |
| 260 | + SET @sql = REPLACE(@command1, @replacechar, @db); |
| 261 | + |
| 262 | + IF @suppress_quotename = 0 SET @sql = REPLACE(REPLACE(@sql,'[[','['),']]',']'); |
| 263 | + |
| 264 | + IF @print_command_only = 1 |
| 265 | + BEGIN |
| 266 | + PRINT '/* For ' + @db + ': */' + CHAR(13) + CHAR(10) |
| 267 | + + CHAR(13) + CHAR(10) + @sql + CHAR(13) + CHAR(10) |
| 268 | + + CHAR(13) + CHAR(10); |
| 269 | + END |
| 270 | + ELSE |
| 271 | + BEGIN |
| 272 | + IF @print_dbname = 1 |
| 273 | + BEGIN |
| 274 | + PRINT '/* ' + @db + ' */'; |
| 275 | + END |
| 276 | + |
| 277 | + EXEC sp_executesql @sql; |
| 278 | + END |
| 279 | + |
| 280 | + FETCH NEXT FROM c INTO @db; |
| 281 | + END |
| 282 | + |
| 283 | + CLOSE c; |
| 284 | + DEALLOCATE c; |
| 285 | + END |
| 286 | +GO |
0 commit comments