Ócáid
Mar 31, 11 PM - Apr 2, 11 PM
An ócáid foghlama SQL, Fabric and Power BI is mó. Márta 31 – 2 Aibreán. Bain úsáid as cód FABINSIDER chun $ 400 a shábháil.
Cláraigh inniuNí thacaítear leis an mbrabhsálaí seo a thuilleadh.
Uasghrádú go Microsoft Edge chun leas a bhaint as na gnéithe is déanaí, nuashonruithe slándála, agus tacaíocht theicniúil.
Applies to:
SQL Server
By default both read-write and read-intent access are allowed to the primary replica and no connections are allowed to secondary replicas of an Always On availability group. This topic describes how to configure connection access on an availability replica of an Always On availability group in SQL Server by using SQL Server Management Studio, Transact-SQL, or PowerShell.
For information about the implications of enabling read-only access for a secondary replica and for an introduction to connection access, see About Client Connection Access to Availability Replicas (SQL Server) and Active Secondaries: Readable Secondary Replicas (Always On Availability Groups).
Task | Permissions |
---|---|
To configure replicas when creating an availability group | Requires membership in the sysadmin fixed server role and either CREATE AVAILABILITY GROUP server permission, ALTER ANY AVAILABILITY GROUP permission, or CONTROL SERVER permission. |
To modify an availability replica | Requires ALTER AVAILABILITY GROUP permission on the availability group, CONTROL AVAILABILITY GROUP permission, ALTER ANY AVAILABILITY GROUP permission, or CONTROL SERVER permission. |
To configure access on an availability replica
In Object Explorer, connect to the server instance that hosts the primary replica, and expand the server tree.
Expand the Always On High Availability node and the Availability Groups node.
Click the availability group whose replica you want to change.
Right-click the availability replica, and click Properties.
In the Availability Replica Properties dialog box, you can change the connection access for the primary role and for the secondary role, as follows:
For the secondary role, select a new value from the Readable secondary drop list, as follows:
No
No user connections are allowed to secondary databases of this replica. They are not available for read access. This is the default setting.
Read-intent only
Only read-only connections are allowed to secondary databases of this replica. The secondary database(s) are all available for read access.
Yes
All connections are allowed to secondary databases of this replica, but only for read access. The secondary database(s) are all available for read access.
For the primary role, select a new value from the Connections in primary role drop list, as follows:
Allow all connections
All connections are allowed to the databases in the primary replica. This is the default setting.
Allow read/write connections
When the Application Intent property is set to ReadWrite or the Application Intent connection property is not set, the connection is allowed. Connections where the Application Intent connection property is set to ReadOnly are not allowed. This can help prevent customers from connecting a read-intent work load to the primary replica by mistake. For more information about Application Intent connection property, see Using Connection String Keywords with SQL Server Native Client.
To configure access on an availability replica
Nóta
For an example of this procedure, see Example (Transact-SQL), later in this section.
Connect to the server instance that hosts the primary replica.
If you are specifying a replica for a new availability group, use the CREATE AVAILABILITY GROUPTransact-SQL statement. If you are adding or modifying a replica of an existing availability group, use the ALTER AVAILABILITY GROUPTransact-SQL statement.
To configure connection access for the secondary role, in the ADD REPLICA or MODIFY REPLICA WITH clause, specify the SECONDARY_ROLE option, as follows:
SECONDARY_ROLE ( ALLOW_CONNECTIONS = { NO | READ_ONLY | ALL } )
where,
NO
No direct connections are allowed to secondary databases of this replica. They are not available for read access. This is the default setting.
READ_ONLY
Only read-only connections are allowed to secondary databases of this replica. The secondary database(s) are all available for read access.
ALL
All connections are allowed to secondary databases of this replica, but only for read access. The secondary database(s) are all available for read access.
To configure connection access for the primary role, in the ADD REPLICA or MODIFY REPLICA WITH clause, specify the PRIMARY_ROLE option, as follows:
PRIMARY_ROLE ( ALLOW_CONNECTIONS = { READ_WRITE | ALL } )
where,
READ_WRITE
Connections where the Application Intent connection property is set to ReadOnly are disallowed. When the Application Intent property is set to ReadWrite or the Application Intent connection property is not set, the connection is allowed. For more information about Application Intent connection property, see Using Connection String Keywords with SQL Server Native Client.
ALL
All connections are allowed to the databases in the primary replica. This is the default setting.
The following example adds a secondary replica to an availability group named AG2. A stand-alone server instance, COMPUTER03\HADR_INSTANCE, is specified to host the new availability replica. This replica configured to allow only read-write connections for the primary role and to allow only read-intent connections for secondary role.
ALTER AVAILABILITY GROUP AG2
ADD REPLICA ON
'COMPUTER03\HADR_INSTANCE' WITH
(
ENDPOINT_URL = 'TCP://COMPUTER03:7022',
PRIMARY_ROLE ( ALLOW_CONNECTIONS = READ_WRITE ),
SECONDARY_ROLE (ALLOW_CONNECTIONS = READ_ONLY )
);
GO
To configure access on an availability replica
Nóta
For a code example, see Example (PowerShell), later in this section.
Change directory (cd) to the server instance that hosts the primary replica.
When adding an availability replica to an availability group, use the New-SqlAvailabilityReplica cmdlet. When modifying an existing availability replica, use the Set-SqlAvailabilityReplica cmdlet. The relevant parameters are as follows:
To configure connection access for the secondary role, specify the ConnectionModeInSecondaryRolesecondary_role_keyword parameter, where secondary_role_keyword equals one of the following values:
AllowNoConnections
No direct connections are allowed to the databases in the secondary replica and the databases are not available for read access. This is the default setting.
AllowReadIntentConnectionsOnly
Connections are allowed only to the databases in the secondary replica where the Application Intent property is set to ReadOnly. For more information about this property, see Using Connection String Keywords with SQL Server Native Client.
AllowAllConnections
All connections are allowed to the databases in the secondary replica for read-only access.
To configure connection access for the primary role, specify ConnectionModeInPrimaryRoleprimary_role_keyword, where primary_role_keyword equals one of the following values:
AllowReadWriteConnections
Connections where the Application Intent connection property is set to ReadOnly are disallowed. When the Application Intent property is set to ReadWrite or the Application Intent connection property is not set, the connection is allowed. For more information about Application Intent connection property, see Using Connection String Keywords with SQL Server Native Client.
AllowAllConnections
All connections are allowed to the databases in the primary replica. This is the default setting.
Nóta
To view the syntax of a cmdlet, use the Get-Help cmdlet in the SQL Server PowerShell environment. For more information, see Get Help SQL Server PowerShell.
To set up and use the SQL Server PowerShell provider
The following example, sets the both the ConnectionModeInSecondaryRole and ConnectionModeInPrimaryRole parameters to AllowAllConnections.
Set-Location SQLSERVER:\SQL\PrimaryServer\default\AvailabilityGroups\MyAg
$primaryReplica = Get-Item "AvailabilityReplicas\PrimaryServer"
Set-SqlAvailabilityReplica -ConnectionModeInSecondaryRole "AllowAllConnections" `
-InputObject $primaryReplica
Set-SqlAvailabilityReplica -ConnectionModeInPrimaryRole "AllowAllConnections" `
-InputObject $primaryReplica
Read-only access to a readable secondary replica
When using the bcp Utility or sqlcmd Utility, you can specify read-only access to any secondary replica that is enabled for read-only access by specifying the -K ReadOnly switch.
To enable client applications to connect to readable secondary replicas:
Prerequisite | Link |
---|---|
Ensure that the availability group has a listener. | Create or Configure an Availability Group Listener (SQL Server) |
Configure read-only routing for the availability group. | Configure Read-Only Routing for an Availability Group (SQL Server) |
Factors that might affect triggers and jobs after a failover
If you have triggers and jobs that will fail when running on a non-readable secondary database or on a readable secondary database, you need to script the triggers and jobs to check on a given replica to determine whether the database is a primary database or is a readable secondary database. To obtain this information, use the DATABASEPROPERTYEX function to return the Updateability property of the database. To identify a read-only database, specify READ_ONLY as the value, as follows:
DATABASEPROPERTYEX([db name],'UpdateAbility') = N'READ_ONLY'
To identify a read-write database, specify READ_WRITE as the value.
Configure Read-Only Routing for an Availability Group (SQL Server)
Create or Configure an Availability Group Listener (SQL Server)
Always On: Why there are two options to enable a secondary replica for read workload?
Always On: I just enabled Readable Secondary but my query is blocked?
Always On: Challenges with statistics on ReadOnly database, Database Snapshot and Secondary Replica
Always On: Impact on the primary workload when you run reporting workload on the secondary replica
Always On: Impact of mapping reporting workload on Readable Secondary to Snapshot Isolation
Always On: Minimizing blocking of REDO thread when running reporting workload on Secondary Replica
Overview of Always On Availability Groups (SQL Server)
Active Secondaries: Readable Secondary Replicas (Always On Availability Groups)
About Client Connection Access to Availability Replicas (SQL Server)
Ócáid
Mar 31, 11 PM - Apr 2, 11 PM
An ócáid foghlama SQL, Fabric and Power BI is mó. Márta 31 – 2 Aibreán. Bain úsáid as cód FABINSIDER chun $ 400 a shábháil.
Cláraigh inniuOiliúint
Modúl
Deploy highly available solutions by using Azure SQL - Training
In this module, you'll learn how to deploy highly available solutions by using Azure SQL. You'll also look at architectures and how they affect availability.
Deimhniú
Microsoft Certified: Azure Database Administrator Associate - Certifications
Administer an SQL Server database infrastructure for cloud, on-premises and hybrid relational databases using the Microsoft PaaS relational database offerings.
Doiciméadúchán
Configure read-only routing for an availability group - SQL Server Always On
Automatically route all read-only traffic to a secondary replica using read-only routing for your Always On availability group - using Transact-SQL (T-SQL), or PowerShell.
Offload workload to secondary availability group replica - SQL Server Always On
Learn about offloading read-only queries and reports to a secondary replica of an Always On availability group on SQL Server.
Redirect read/write connections to primary replica - SQL Server Always On
Learn how to redirect read/write connections to the primary replica of an Always On availability group regardless of the server specified in the connection string.