sys.availability_replicas (Transact-SQL)
Returns a row for each of the availability replicas that belong to any AlwaysOn availability group in the WSFC failover cluster.
If the local server instance is unable to talk to the WSFC failover cluster, for example because the cluster is down or quorum has been lost, only rows for local availability replicas are returned. These rows will contain only the columns of data that are cached locally in metadata.
Column name |
Data type |
Description |
||||||
---|---|---|---|---|---|---|---|---|
replica_id |
uniqueidentifier |
Unique ID of the replica. |
||||||
group_id |
uniqueidentifier |
Unique ID of the availability group to which the replica belongs. |
||||||
replica_metadata_id |
int |
ID for the local metadata object for availability replicas in the Database Engine. |
||||||
replica_server_name |
nvarchar(256) |
Server name of the instance of SQL Server that is hosting this replica and, for a non-default instance, its instance name. |
||||||
owner_sid |
varbinary(85) |
Security identifier (SID) registered to this server instance for the external owner of this availability replica. NULL for non-local availability replicas. |
||||||
endpoint_url |
nvarchar(128) |
String representation of the user-specified database mirroring endpoint that is used by connections between primary and secondary replicas for data synchronization. For information about the syntax of endpoint URLs, see Specify the Endpoint URL When Adding or Modifying an Availability Replica (SQL Server). NULL = Unable to talk to the WSFC failover cluster. To change this endpoint, use the ENDPOINT_URL option of ALTER AVAILABILITY GROUP Transact-SQL statement. |
||||||
availability_mode |
tinyint |
The availability mode of the replica, one of:
For more information, see Availability Modes (AlwaysOn Availability Groups). |
||||||
availability_mode_desc |
nvarchar(60) |
Description of availability_mode, one of: ASYNCHRONOUS_COMMIT SYNCHRONOUS_COMMIT To change this the availability mode of an availability replica, use the AVAILABILITY_MODE option of ALTER AVAILABILITY GROUP Transact-SQL statement. |
||||||
failover_mode |
tinyint |
The failover mode of the availability replica, one of:
To view a rollup of the database synchronization health of every availability database in an availability replica, use the synchronization_health and synchronization_health_desc columns of the sys.dm_hadr_availability_replica_states dynamic management view. The rollup considers the synchronization state of every availability database and the availability mode of its availability replica. Tip To view the synchronization health of a given availability database, query the synchronization_state and synchronization_health columns of the sys.dm_hadr_database_replica_states dynamic management view. |
||||||
failover_mode_desc |
nvarchar(60) |
Description of failover_mode, one of: MANUAL AUTOMATIC To change the failover mode, use the FAILOVER_MODE option of ALTER AVAILABILITY GROUP Transact-SQL statement. |
||||||
session_timeout |
int |
The time-out period, in seconds. The time-out period is the maximum time that the replica waits to receive a message from another replica before considering connection between the primary and secondary replica have failed. Session timeout detects whether secondaries are connected the primary replica. On detecting a failed connection with a secondary replica, the primary replica considers the secondary replica to be NOT_SYNCHRONIZED. On detecting a failed connection with the primary replica, a secondary replica simply attempts to reconnect. Note Session timeouts do not cause automatic failovers. To change this value, use the SESSION_TIMEOUT option of ALTER AVAILABILITY GROUP Transact-SQL statement. |
||||||
primary_role_allow_connections |
tinyint |
Whether the availability allows all connections or only read-write connections, one of: 2 = All (default) 3 = Read write |
||||||
primary_role_allow_connections_desc |
nvarchar(60) |
Description of primary_role_allow_connections, one of: ALL READ_WRITE |
||||||
secondary_role_allow_connections |
tinyint |
Whether an availability replica that is performing the secondary role (that is, a secondary replica) can accept connections from clients, one of: 0 = No. No connections are allowed to the databases in the secondary replica, and the databases are not available for read access. This is the default setting. 1 = Read only. Only read-only connections are allowed to the databases in the secondary replica. All database(s) in the replica are available for read access. 2 = All. All connections are allowed to the databases in the secondary replica for read-only access. For more information, see Active Secondaries: Readable Secondary Replicas (AlwaysOn Availability Groups). |
||||||
secondary_role_allow_connections_desc |
nvarchar(60) |
Description of secondary_role_allow_connections, one of: NO READ_ONLY ALL |
||||||
create_date |
datetime |
Date that the replica was created. NULL = Replica not on this server instance. |
||||||
modify_date |
datetime |
Date that the replica was last modified. NULL = Replica not on this server instance. |
||||||
backup_priority |
int |
Represents the user-specified priority for performing backups on this replica relative to the other replicas in the same availability group. The value is an integer in the range of 0..100. For more information, see Active Secondaries: Backup on Secondary Replicas (AlwaysOn Availability Groups). |
||||||
read_only_routing_url |
nvarchar(256) |
Connectivity endpoint (URL) of the read only availability replica. For more information, see Configure Read-Only Routing for an Availability Group (SQL Server). |
Security
Permissions
Requires VIEW ANY DEFINITION permission on the server instance.
See Also
Reference
sys.availability_groups (Transact-SQL)
Concepts
Overview of AlwaysOn Availability Groups (SQL Server)
AlwaysOn Availability Groups (SQL Server)