function to check whether the current server is involved in an availability group and if so, whether it is...












2














I used to have 2 servers on an availability group, but there was a problem with one of them servers involved,while patching, and to make a long story short I removed all the databases from the availability group.



The way I managed execution of jobs only in the primary server was mainly through this script which tests whether the database is in the primary replica:



  If sys.fn_hadr_is_primary_replica ('apcore') =1  
BEGIN


EXEC [APCore].[app].[usp_upd_applicationStatusTimeExpired]

END


But now that the current server is the only server in the Availability group,
this script



  select sys.fn_hadr_is_primary_replica ('apcore')


retuns null, and therefore is not accurate.



I have been developing a function that should return a bit 1 in one of the following cases:



1 - we are not part of an availability group



2 - we are part of an availability group and we are the primary server



The question is:



Would this function work for a distributed availability group?
Is there any other situation that I haven't thought of that might prevent this function to return the expected value?



and here is the function:
the function is to be used inside jobs and check whether we should run the job (either because we are in an availability group and we are the primary, or we are not in an availability group at all).



--=========================================
-- scalar-valued function dbo.check_HADR_status
-- returns 1 when either primary or we are standalone
-- (not part of an availability group)

-- USAGE:
-- SELECT MASTER.dbo.check_HADR_status()
--=========================================

USE MASTER
GO

IF OBJECT_ID (N'dbo.check_HADR_status') IS NOT NULL
DROP FUNCTION dbo.check_HADR_status
GO

CREATE FUNCTION dbo.check_HADR_status()
RETURNS BIT
WITH EXECUTE AS CALLER
AS
BEGIN
RETURN (SELECT CASE WHEN EXISTS (select * from sys.availability_replicas) THEN
CASE WHEN ( SELECT COALESCE(a.role_desc,'RADHE')
FROM sys.dm_hadr_availability_replica_states AS a
JOIN sys.availability_replicas AS b
ON b.replica_id = a.replica_id
WHERE b.replica_server_name = @@ServerName) LIKE 'PRIMARY' THEN 1
ELSE 0
END
ELSE 1
END)
END
GO


IF (SELECT MASTER.dbo.check_HADR_status()) = 1
BEGIN
PRINT 'RUN THE JOB STEP'
END
ELSE
BEGIN
PRINT 'DON''T RUN THE JOB AS WE ARE IN A SECONDARY REPLICA'
END









share|improve this question
























  • wouldn't it be easier to just say = 1 or isnull and use the built in?
    – Sean Gallardy
    12 hours ago


















2














I used to have 2 servers on an availability group, but there was a problem with one of them servers involved,while patching, and to make a long story short I removed all the databases from the availability group.



The way I managed execution of jobs only in the primary server was mainly through this script which tests whether the database is in the primary replica:



  If sys.fn_hadr_is_primary_replica ('apcore') =1  
BEGIN


EXEC [APCore].[app].[usp_upd_applicationStatusTimeExpired]

END


But now that the current server is the only server in the Availability group,
this script



  select sys.fn_hadr_is_primary_replica ('apcore')


retuns null, and therefore is not accurate.



I have been developing a function that should return a bit 1 in one of the following cases:



1 - we are not part of an availability group



2 - we are part of an availability group and we are the primary server



The question is:



Would this function work for a distributed availability group?
Is there any other situation that I haven't thought of that might prevent this function to return the expected value?



and here is the function:
the function is to be used inside jobs and check whether we should run the job (either because we are in an availability group and we are the primary, or we are not in an availability group at all).



--=========================================
-- scalar-valued function dbo.check_HADR_status
-- returns 1 when either primary or we are standalone
-- (not part of an availability group)

-- USAGE:
-- SELECT MASTER.dbo.check_HADR_status()
--=========================================

USE MASTER
GO

IF OBJECT_ID (N'dbo.check_HADR_status') IS NOT NULL
DROP FUNCTION dbo.check_HADR_status
GO

CREATE FUNCTION dbo.check_HADR_status()
RETURNS BIT
WITH EXECUTE AS CALLER
AS
BEGIN
RETURN (SELECT CASE WHEN EXISTS (select * from sys.availability_replicas) THEN
CASE WHEN ( SELECT COALESCE(a.role_desc,'RADHE')
FROM sys.dm_hadr_availability_replica_states AS a
JOIN sys.availability_replicas AS b
ON b.replica_id = a.replica_id
WHERE b.replica_server_name = @@ServerName) LIKE 'PRIMARY' THEN 1
ELSE 0
END
ELSE 1
END)
END
GO


IF (SELECT MASTER.dbo.check_HADR_status()) = 1
BEGIN
PRINT 'RUN THE JOB STEP'
END
ELSE
BEGIN
PRINT 'DON''T RUN THE JOB AS WE ARE IN A SECONDARY REPLICA'
END









share|improve this question
























  • wouldn't it be easier to just say = 1 or isnull and use the built in?
    – Sean Gallardy
    12 hours ago
















2












2








2


1





I used to have 2 servers on an availability group, but there was a problem with one of them servers involved,while patching, and to make a long story short I removed all the databases from the availability group.



The way I managed execution of jobs only in the primary server was mainly through this script which tests whether the database is in the primary replica:



  If sys.fn_hadr_is_primary_replica ('apcore') =1  
BEGIN


EXEC [APCore].[app].[usp_upd_applicationStatusTimeExpired]

END


But now that the current server is the only server in the Availability group,
this script



  select sys.fn_hadr_is_primary_replica ('apcore')


retuns null, and therefore is not accurate.



I have been developing a function that should return a bit 1 in one of the following cases:



1 - we are not part of an availability group



2 - we are part of an availability group and we are the primary server



The question is:



Would this function work for a distributed availability group?
Is there any other situation that I haven't thought of that might prevent this function to return the expected value?



and here is the function:
the function is to be used inside jobs and check whether we should run the job (either because we are in an availability group and we are the primary, or we are not in an availability group at all).



--=========================================
-- scalar-valued function dbo.check_HADR_status
-- returns 1 when either primary or we are standalone
-- (not part of an availability group)

-- USAGE:
-- SELECT MASTER.dbo.check_HADR_status()
--=========================================

USE MASTER
GO

IF OBJECT_ID (N'dbo.check_HADR_status') IS NOT NULL
DROP FUNCTION dbo.check_HADR_status
GO

CREATE FUNCTION dbo.check_HADR_status()
RETURNS BIT
WITH EXECUTE AS CALLER
AS
BEGIN
RETURN (SELECT CASE WHEN EXISTS (select * from sys.availability_replicas) THEN
CASE WHEN ( SELECT COALESCE(a.role_desc,'RADHE')
FROM sys.dm_hadr_availability_replica_states AS a
JOIN sys.availability_replicas AS b
ON b.replica_id = a.replica_id
WHERE b.replica_server_name = @@ServerName) LIKE 'PRIMARY' THEN 1
ELSE 0
END
ELSE 1
END)
END
GO


IF (SELECT MASTER.dbo.check_HADR_status()) = 1
BEGIN
PRINT 'RUN THE JOB STEP'
END
ELSE
BEGIN
PRINT 'DON''T RUN THE JOB AS WE ARE IN A SECONDARY REPLICA'
END









share|improve this question















I used to have 2 servers on an availability group, but there was a problem with one of them servers involved,while patching, and to make a long story short I removed all the databases from the availability group.



The way I managed execution of jobs only in the primary server was mainly through this script which tests whether the database is in the primary replica:



  If sys.fn_hadr_is_primary_replica ('apcore') =1  
BEGIN


EXEC [APCore].[app].[usp_upd_applicationStatusTimeExpired]

END


But now that the current server is the only server in the Availability group,
this script



  select sys.fn_hadr_is_primary_replica ('apcore')


retuns null, and therefore is not accurate.



I have been developing a function that should return a bit 1 in one of the following cases:



1 - we are not part of an availability group



2 - we are part of an availability group and we are the primary server



The question is:



Would this function work for a distributed availability group?
Is there any other situation that I haven't thought of that might prevent this function to return the expected value?



and here is the function:
the function is to be used inside jobs and check whether we should run the job (either because we are in an availability group and we are the primary, or we are not in an availability group at all).



--=========================================
-- scalar-valued function dbo.check_HADR_status
-- returns 1 when either primary or we are standalone
-- (not part of an availability group)

-- USAGE:
-- SELECT MASTER.dbo.check_HADR_status()
--=========================================

USE MASTER
GO

IF OBJECT_ID (N'dbo.check_HADR_status') IS NOT NULL
DROP FUNCTION dbo.check_HADR_status
GO

CREATE FUNCTION dbo.check_HADR_status()
RETURNS BIT
WITH EXECUTE AS CALLER
AS
BEGIN
RETURN (SELECT CASE WHEN EXISTS (select * from sys.availability_replicas) THEN
CASE WHEN ( SELECT COALESCE(a.role_desc,'RADHE')
FROM sys.dm_hadr_availability_replica_states AS a
JOIN sys.availability_replicas AS b
ON b.replica_id = a.replica_id
WHERE b.replica_server_name = @@ServerName) LIKE 'PRIMARY' THEN 1
ELSE 0
END
ELSE 1
END)
END
GO


IF (SELECT MASTER.dbo.check_HADR_status()) = 1
BEGIN
PRINT 'RUN THE JOB STEP'
END
ELSE
BEGIN
PRINT 'DON''T RUN THE JOB AS WE ARE IN A SECONDARY REPLICA'
END






sql-server sql-server-2016 availability-groups jobs distributed-availability-groups






share|improve this question















share|improve this question













share|improve this question




share|improve this question








edited Jan 3 at 18:05

























asked Jan 3 at 16:28









marcello miorelli

5,6211960129




5,6211960129












  • wouldn't it be easier to just say = 1 or isnull and use the built in?
    – Sean Gallardy
    12 hours ago




















  • wouldn't it be easier to just say = 1 or isnull and use the built in?
    – Sean Gallardy
    12 hours ago


















wouldn't it be easier to just say = 1 or isnull and use the built in?
– Sean Gallardy
12 hours ago






wouldn't it be easier to just say = 1 or isnull and use the built in?
– Sean Gallardy
12 hours ago












1 Answer
1






active

oldest

votes


















3














We use Distributed Availability Groups (and some servers that are just in a straight AG) and ran into a similar issue. We eventually settled on this query as our end all, be all solution. It's probably more complicated than it needs to be, but it does work.



DECLARE @DBName sysname;
DECLARE @IsPrimary BIT = 0;

--Determine if the database selected is online.
;WITH CTE_DAG
AS
( SELECT AG.[name] AS DAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
WHERE AG.is_distributed = 1)
, CTE_LocalAG
AS
( SELECT AG.[name] AS LocalAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
, D.[name] AS DatabaseName
, DRS.is_primary_replica
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
INNER JOIN sys.dm_hadr_availability_replica_cluster_states AS ARCS ON ARCS.group_id = AG.group_id
LEFT OUTER JOIN sys.dm_hadr_database_replica_states AS DRS ON DRS.replica_id = ARCS.replica_id
AND DRS.group_id = ARCS.group_id
INNER JOIN sys.databases AS D ON D.database_id = DRS.database_id
WHERE AG.is_distributed = 0
AND ARCS.replica_server_name = @@SERVERNAME)
, CTE_Composite
AS
( SELECT L.DatabaseName
, L.role_desc
, L.is_primary_replica
, COALESCE(D.role_desc, 'NONE') AS DAG_Role
, IsAllPrimary = CASE WHEN L.is_primary_replica = 1
AND COALESCE(D.role_desc, 'NONE') IN ('NONE', 'PRIMARY')
THEN 1
ELSE 0
END
FROM CTE_LocalAG AS L
LEFT OUTER JOIN CTE_DAG AS D ON D.UnderlyingAG = L.LocalAGName
WHERE L.DatabaseName = @DBName)
, CTE_Grouping
AS
( SELECT DatabaseName
, SUM(IsAllPrimary) AS TotalPrimary
, COUNT(DatabaseName) AS TotalCount
FROM CTE_Composite
GROUP BY DatabaseName)
SELECT TOP (1)
@IsPrimary = 1
FROM CTE_Grouping
WHERE COALESCE(TotalPrimary, 0) = COALESCE(TotalCount, 0);





share|improve this answer





















  • that's great, looks beautiful
    – marcello miorelli
    Jan 3 at 18:14











Your Answer








StackExchange.ready(function() {
var channelOptions = {
tags: "".split(" "),
id: "182"
};
initTagRenderer("".split(" "), "".split(" "), channelOptions);

StackExchange.using("externalEditor", function() {
// Have to fire editor after snippets, if snippets enabled
if (StackExchange.settings.snippets.snippetsEnabled) {
StackExchange.using("snippets", function() {
createEditor();
});
}
else {
createEditor();
}
});

function createEditor() {
StackExchange.prepareEditor({
heartbeatType: 'answer',
autoActivateHeartbeat: false,
convertImagesToLinks: false,
noModals: true,
showLowRepImageUploadWarning: true,
reputationToPostImages: null,
bindNavPrevention: true,
postfix: "",
imageUploader: {
brandingHtml: "Powered by u003ca class="icon-imgur-white" href="https://imgur.com/"u003eu003c/au003e",
contentPolicyHtml: "User contributions licensed under u003ca href="https://creativecommons.org/licenses/by-sa/3.0/"u003ecc by-sa 3.0 with attribution requiredu003c/au003e u003ca href="https://stackoverflow.com/legal/content-policy"u003e(content policy)u003c/au003e",
allowUrls: true
},
onDemand: true,
discardSelector: ".discard-answer"
,immediatelyShowMarkdownHelp:true
});


}
});














draft saved

draft discarded


















StackExchange.ready(
function () {
StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fdba.stackexchange.com%2fquestions%2f226266%2ffunction-to-check-whether-the-current-server-is-involved-in-an-availability-grou%23new-answer', 'question_page');
}
);

Post as a guest















Required, but never shown

























1 Answer
1






active

oldest

votes








1 Answer
1






active

oldest

votes









active

oldest

votes






active

oldest

votes









3














We use Distributed Availability Groups (and some servers that are just in a straight AG) and ran into a similar issue. We eventually settled on this query as our end all, be all solution. It's probably more complicated than it needs to be, but it does work.



DECLARE @DBName sysname;
DECLARE @IsPrimary BIT = 0;

--Determine if the database selected is online.
;WITH CTE_DAG
AS
( SELECT AG.[name] AS DAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
WHERE AG.is_distributed = 1)
, CTE_LocalAG
AS
( SELECT AG.[name] AS LocalAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
, D.[name] AS DatabaseName
, DRS.is_primary_replica
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
INNER JOIN sys.dm_hadr_availability_replica_cluster_states AS ARCS ON ARCS.group_id = AG.group_id
LEFT OUTER JOIN sys.dm_hadr_database_replica_states AS DRS ON DRS.replica_id = ARCS.replica_id
AND DRS.group_id = ARCS.group_id
INNER JOIN sys.databases AS D ON D.database_id = DRS.database_id
WHERE AG.is_distributed = 0
AND ARCS.replica_server_name = @@SERVERNAME)
, CTE_Composite
AS
( SELECT L.DatabaseName
, L.role_desc
, L.is_primary_replica
, COALESCE(D.role_desc, 'NONE') AS DAG_Role
, IsAllPrimary = CASE WHEN L.is_primary_replica = 1
AND COALESCE(D.role_desc, 'NONE') IN ('NONE', 'PRIMARY')
THEN 1
ELSE 0
END
FROM CTE_LocalAG AS L
LEFT OUTER JOIN CTE_DAG AS D ON D.UnderlyingAG = L.LocalAGName
WHERE L.DatabaseName = @DBName)
, CTE_Grouping
AS
( SELECT DatabaseName
, SUM(IsAllPrimary) AS TotalPrimary
, COUNT(DatabaseName) AS TotalCount
FROM CTE_Composite
GROUP BY DatabaseName)
SELECT TOP (1)
@IsPrimary = 1
FROM CTE_Grouping
WHERE COALESCE(TotalPrimary, 0) = COALESCE(TotalCount, 0);





share|improve this answer





















  • that's great, looks beautiful
    – marcello miorelli
    Jan 3 at 18:14
















3














We use Distributed Availability Groups (and some servers that are just in a straight AG) and ran into a similar issue. We eventually settled on this query as our end all, be all solution. It's probably more complicated than it needs to be, but it does work.



DECLARE @DBName sysname;
DECLARE @IsPrimary BIT = 0;

--Determine if the database selected is online.
;WITH CTE_DAG
AS
( SELECT AG.[name] AS DAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
WHERE AG.is_distributed = 1)
, CTE_LocalAG
AS
( SELECT AG.[name] AS LocalAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
, D.[name] AS DatabaseName
, DRS.is_primary_replica
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
INNER JOIN sys.dm_hadr_availability_replica_cluster_states AS ARCS ON ARCS.group_id = AG.group_id
LEFT OUTER JOIN sys.dm_hadr_database_replica_states AS DRS ON DRS.replica_id = ARCS.replica_id
AND DRS.group_id = ARCS.group_id
INNER JOIN sys.databases AS D ON D.database_id = DRS.database_id
WHERE AG.is_distributed = 0
AND ARCS.replica_server_name = @@SERVERNAME)
, CTE_Composite
AS
( SELECT L.DatabaseName
, L.role_desc
, L.is_primary_replica
, COALESCE(D.role_desc, 'NONE') AS DAG_Role
, IsAllPrimary = CASE WHEN L.is_primary_replica = 1
AND COALESCE(D.role_desc, 'NONE') IN ('NONE', 'PRIMARY')
THEN 1
ELSE 0
END
FROM CTE_LocalAG AS L
LEFT OUTER JOIN CTE_DAG AS D ON D.UnderlyingAG = L.LocalAGName
WHERE L.DatabaseName = @DBName)
, CTE_Grouping
AS
( SELECT DatabaseName
, SUM(IsAllPrimary) AS TotalPrimary
, COUNT(DatabaseName) AS TotalCount
FROM CTE_Composite
GROUP BY DatabaseName)
SELECT TOP (1)
@IsPrimary = 1
FROM CTE_Grouping
WHERE COALESCE(TotalPrimary, 0) = COALESCE(TotalCount, 0);





share|improve this answer





















  • that's great, looks beautiful
    – marcello miorelli
    Jan 3 at 18:14














3












3








3






We use Distributed Availability Groups (and some servers that are just in a straight AG) and ran into a similar issue. We eventually settled on this query as our end all, be all solution. It's probably more complicated than it needs to be, but it does work.



DECLARE @DBName sysname;
DECLARE @IsPrimary BIT = 0;

--Determine if the database selected is online.
;WITH CTE_DAG
AS
( SELECT AG.[name] AS DAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
WHERE AG.is_distributed = 1)
, CTE_LocalAG
AS
( SELECT AG.[name] AS LocalAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
, D.[name] AS DatabaseName
, DRS.is_primary_replica
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
INNER JOIN sys.dm_hadr_availability_replica_cluster_states AS ARCS ON ARCS.group_id = AG.group_id
LEFT OUTER JOIN sys.dm_hadr_database_replica_states AS DRS ON DRS.replica_id = ARCS.replica_id
AND DRS.group_id = ARCS.group_id
INNER JOIN sys.databases AS D ON D.database_id = DRS.database_id
WHERE AG.is_distributed = 0
AND ARCS.replica_server_name = @@SERVERNAME)
, CTE_Composite
AS
( SELECT L.DatabaseName
, L.role_desc
, L.is_primary_replica
, COALESCE(D.role_desc, 'NONE') AS DAG_Role
, IsAllPrimary = CASE WHEN L.is_primary_replica = 1
AND COALESCE(D.role_desc, 'NONE') IN ('NONE', 'PRIMARY')
THEN 1
ELSE 0
END
FROM CTE_LocalAG AS L
LEFT OUTER JOIN CTE_DAG AS D ON D.UnderlyingAG = L.LocalAGName
WHERE L.DatabaseName = @DBName)
, CTE_Grouping
AS
( SELECT DatabaseName
, SUM(IsAllPrimary) AS TotalPrimary
, COUNT(DatabaseName) AS TotalCount
FROM CTE_Composite
GROUP BY DatabaseName)
SELECT TOP (1)
@IsPrimary = 1
FROM CTE_Grouping
WHERE COALESCE(TotalPrimary, 0) = COALESCE(TotalCount, 0);





share|improve this answer












We use Distributed Availability Groups (and some servers that are just in a straight AG) and ran into a similar issue. We eventually settled on this query as our end all, be all solution. It's probably more complicated than it needs to be, but it does work.



DECLARE @DBName sysname;
DECLARE @IsPrimary BIT = 0;

--Determine if the database selected is online.
;WITH CTE_DAG
AS
( SELECT AG.[name] AS DAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
WHERE AG.is_distributed = 1)
, CTE_LocalAG
AS
( SELECT AG.[name] AS LocalAGName
, AG.is_distributed
, AR.replica_server_name AS UnderlyingAG
, ARS.role_desc
, D.[name] AS DatabaseName
, DRS.is_primary_replica
FROM sys.availability_groups AS AG
INNER JOIN sys.availability_replicas AS AR ON AR.group_id = AG.group_id
INNER JOIN sys.dm_hadr_availability_replica_states AS ARS ON ARS.replica_id = AR.replica_id
INNER JOIN sys.dm_hadr_availability_replica_cluster_states AS ARCS ON ARCS.group_id = AG.group_id
LEFT OUTER JOIN sys.dm_hadr_database_replica_states AS DRS ON DRS.replica_id = ARCS.replica_id
AND DRS.group_id = ARCS.group_id
INNER JOIN sys.databases AS D ON D.database_id = DRS.database_id
WHERE AG.is_distributed = 0
AND ARCS.replica_server_name = @@SERVERNAME)
, CTE_Composite
AS
( SELECT L.DatabaseName
, L.role_desc
, L.is_primary_replica
, COALESCE(D.role_desc, 'NONE') AS DAG_Role
, IsAllPrimary = CASE WHEN L.is_primary_replica = 1
AND COALESCE(D.role_desc, 'NONE') IN ('NONE', 'PRIMARY')
THEN 1
ELSE 0
END
FROM CTE_LocalAG AS L
LEFT OUTER JOIN CTE_DAG AS D ON D.UnderlyingAG = L.LocalAGName
WHERE L.DatabaseName = @DBName)
, CTE_Grouping
AS
( SELECT DatabaseName
, SUM(IsAllPrimary) AS TotalPrimary
, COUNT(DatabaseName) AS TotalCount
FROM CTE_Composite
GROUP BY DatabaseName)
SELECT TOP (1)
@IsPrimary = 1
FROM CTE_Grouping
WHERE COALESCE(TotalPrimary, 0) = COALESCE(TotalCount, 0);






share|improve this answer












share|improve this answer



share|improve this answer










answered Jan 3 at 18:11









Jonathan Fite

3,955818




3,955818












  • that's great, looks beautiful
    – marcello miorelli
    Jan 3 at 18:14


















  • that's great, looks beautiful
    – marcello miorelli
    Jan 3 at 18:14
















that's great, looks beautiful
– marcello miorelli
Jan 3 at 18:14




that's great, looks beautiful
– marcello miorelli
Jan 3 at 18:14


















draft saved

draft discarded




















































Thanks for contributing an answer to Database Administrators Stack Exchange!


  • Please be sure to answer the question. Provide details and share your research!

But avoid



  • Asking for help, clarification, or responding to other answers.

  • Making statements based on opinion; back them up with references or personal experience.


To learn more, see our tips on writing great answers.





Some of your past answers have not been well-received, and you're in danger of being blocked from answering.


Please pay close attention to the following guidance:


  • Please be sure to answer the question. Provide details and share your research!

But avoid



  • Asking for help, clarification, or responding to other answers.

  • Making statements based on opinion; back them up with references or personal experience.


To learn more, see our tips on writing great answers.




draft saved


draft discarded














StackExchange.ready(
function () {
StackExchange.openid.initPostLogin('.new-post-login', 'https%3a%2f%2fdba.stackexchange.com%2fquestions%2f226266%2ffunction-to-check-whether-the-current-server-is-involved-in-an-availability-grou%23new-answer', 'question_page');
}
);

Post as a guest















Required, but never shown





















































Required, but never shown














Required, but never shown












Required, but never shown







Required, but never shown

































Required, but never shown














Required, but never shown












Required, but never shown







Required, but never shown







Popular posts from this blog

"Incorrect syntax near the keyword 'ON'. (on update cascade, on delete cascade,)

Alcedinidae

RAC Tourist Trophy