T SQL help in Testing Always on Availability Groups job

  • I have Setup Always on Availability Groups between 2 servers and i have a Script that i wanted to put in Job and i want to run the job only on primary at any time..(one active and one secondary)

    USE MASTER

    GO

    DECLARE @ServerName NVARCHAR(256) = @@SERVERNAME

    DECLARE @RoleDesc NVARCHAR(60)

    SELECT @RoleDesc = a.role_desc

    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

    IF @RoleDesc = 'PRIMARY'

    BEGIN

    USE TestAG

    Insert into CheckAvailabilityRoleJobs(InsertDate,ServerName,RoleDescription)

    SELECT GETDATE(),@@SERVERNAME, a.role_desc

    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

    END

    ELSE

    BEGIN

    RETURN

    END

    I wanted to keep this job running 24X7 on both servers, but insert happens only on Primary at any time , in secondary the JOB exits with out actually inserting...

    the script is running good on PRIMARY, but when i try to run on SECONDARY it is failing ...

    the script should actually exit on SECONDARY after checking Primary or not but it is trying too connect TESTAG database which is not accessible on secondary

    Msg 976, Level 14, State 1, Line 16

    The target database, 'TestAG', is participating in an availability group and is currently not accessible for queries. Either data movement is suspended or the availability replica is not enabled for read access. To allow read-only access to this and other databases in the availability group, enable read access to one or more secondary availability replicas in the group. For more information, see the ALTER AVAILABILITY GROUP statement in SQL Server Books Online.

    any help?

  • Try the following code in your jobstep on both servers.

    if (select

    ars.role_desc

    from sys.dm_hadr_availability_replica_states ars

    inner join sys.availability_groups ag

    on ars.group_id = ag.group_id

    where ag.name = 'name of your AG group' -- you need to edit this line!!

    and ars.is_local = 1) = 'PRIMARY'

    begin

    insert your stored procedure here (EXEC database.schema.sp)-- you need to edit this line!! because SQL server parses your code this needs to be a stored procedure to avoid errors.

    end

    As database for the job, select master

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply