Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Update sp_ineachdb.sql #2061

Merged
merged 1 commit into from Jul 2, 2019
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
26 changes: 14 additions & 12 deletions sp_ineachdb.sql
@@ -1,8 +1,8 @@
IF OBJECT_ID('dbo.sp_ineachdb') IS NULL
EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0');
EXEC ('CREATE PROCEDURE dbo.sp_ineachdb AS RETURN 0')
GO

ALTER PROCEDURE dbo.sp_ineachdb
ALTER PROCEDURE [dbo].[sp_ineachdb]
-- mssqltips.com/sqlservertip/5694/execute-a-command-in-the-context-of-each-database-in-sql-server--part-2/
@command nvarchar(max) = NULL,
@replace_character nchar(1) = N'?',
Expand Down Expand Up @@ -99,6 +99,9 @@ IF @Help = 1
@thisdb sysname,
@cr char(2) = CHAR(13) + CHAR(10);

DECLARE @SQLVersion AS tinyint = (@@microsoftversion / 0x1000000) & 0xff -- Stores the SQL Server Version Number(8(2000),9(2005),10(2008 & 2008R2),11(2012),12(2014),13(2016),14(2017))
DECLARE @ServerName AS sysname = CONVERT(sysname, SERVERPROPERTY('ServerName')) -- Stores the SQL Server Instance name.

CREATE TABLE #ineachdb(id int, name nvarchar(512));

IF @database_list > N''
Expand Down Expand Up @@ -190,12 +193,14 @@ IF @Help = 1
-- https://docs.microsoft.com/en-us/sql/t-sql/functions/databasepropertyex-transact-sql
)
OR (@state_desc <> N'ONLINE' AND state_desc <> @state_desc)
OR
(
-- from Andy Mallon / First Responders Kit. Make sure that if we're an
-- AG secondary, we skip any database where allow connections is off
SERVERPROPERTY('IsHadrEnabled') = 1
AND EXISTS
)
);

-- from Andy Mallon / First Responders Kit. Make sure that if we're an
-- AG secondary, we skip any database where allow connections is off
if @SQLVersion >= 11
DELETE dbs FROM #ineachdb AS dbs
WHERE EXISTS
(
SELECT 1 FROM sys.dm_hadr_database_replica_states AS drs
INNER JOIN sys.availability_replicas AS ar
Expand All @@ -204,10 +209,7 @@ IF @Help = 1
ON ags.group_id = ar.group_id
WHERE drs.database_id = dbs.id
AND ar.secondary_role_allow_connections = 0
AND ags.primary_replica <> @@SERVERNAME
)
)
)
AND ags.primary_replica <> @ServerName
);

-- Well, if we deleted them all...
Expand Down