Blog Post

AlwaysOn: Configuring Secondary Read-Only Access

,

Now that you have AlwaysOn configured and your first Availability Group (AG) created, it’s time to start leveraging those secondary replicas.  The first step is to set the connection access for the primary and secondary role, if you haven’t already done so.  You have three choices:

  1. No:  No user connections are allowed to the secondary replica.
  2. Read-intent only:  Only read-only connections are allowed
  3. Yes:  All connections are allowed, but only for read-only access

So the main difference between Read-intent-only and Yes is that the later allows all connections, regardless if it read or read/write, but only read access will be granted.  If you did not set the properties during AG creation you can use TSQL, PowerShell or Management Studio to update the configuration. 

If you have not configured your secondary replicas for read-only access open management studio, locate and expand the AlwaysOn High Availability folder.  From there expand the Availability Group folder, locate your AG and right-click it.  In the Availability Replicas section of the AG Properties screen, locate the replica you want to configure for read-only access and change the Readable Secondary Property. 

image

Click OK. 

Now, before you can actually read the secondary, in addition to setting the Readable Secondary property you will also need to perform two additional configurations.  First you will need to have a AG Listener configured. If you have not configured the AG Listener you can do so using Management Studio.

To create a listener with Management Studio:

  1. Expand the AlwaysOn High Availability folder, expand Availability Groups, locate and expand the AG that needs the Listener. 
  2. Next right-click the Availability Group Listeners folder and select Add Listener.
  3. On the Add Listener dialogue box specify the following:
    1. Listener DNS:  Network Name
    2. Port:  TPC port
    3. Network Mode:  TCP protocol (DHCP, Static IP)

Now you have a listener.  You can now connect to management studio using this Listener DNS.  Give it a try. 

The final step is to configure Read-only routing, which is the ability of SQL Server to route incoming connections to the Listener to a secondary that is configured for read-only access.  The read-only routing only works if the client connects using the AG Listener and the ApplicationIntent property is set to ReadOnly in the connection string. 

To configure the read-only routing you must first set a READ_ONLY_ROUTING_URL for each replica.  A sample script is as follows:

ALTER AVAILABILITY GROUP [PatricksAG]
MODIFY REPLICA ON
N’SQLAlwaysOn1′ WITH
(SECONDARY_ROLE (READ_ONLY_ROUTING_URL = N’TCP://SQLAlwaysOn1.domain.com:1433′));

You must set this option for each replica.  After you have done this you must set the READ_ONLY_ROUTING_LIST for each replica.  This list specifies how the routing will take place in the order the targets are specified.  A sample script is as follows:

ALTER AVAILABILITY GROUP [PatricksAG]
MODIFY REPLICA ON
N’SQLAlwaysOn1′ WITH
(PRIMARY_ROLE (READ_ONLY_ROUTING_LIST=(‘SQLAlwaysOn2′,’SQLAlwaysOn3′, ‘SQLAlwaysOn1′)));

Again this must be set for each replica.  Once these steps are complete, you can now use the ApplicationIntent property in your connection strings.  This property can be used with the SQL Server Native Client OLE DB provider and ODBC driver, and ActiveX Data Objects (ADO).  The following is a sample connecting string:

Server=tcp:AGListener, 1433;Database=AlwaysOnDB1;IntegratedSecurity=SSPI;ApplicationIntent=ReadOnly

If an application connected using the above connection string it would be routed to one of the secondary replicas. 

If you want to see the affects of using Read-intent only over Yes give this a try.  First set the Readable Secondary property of one of your secondary replicas to Yes.  Using Management Studio connect to the secondary using the physical machine name not the AG Listener name.

USE<Your Database Name>
GO
SELECT * FROM INFORMATION_SCHEMA.tables

In the USE statement you should include a database that is one of your Availability Databases.  Run this query and it should yield results.  Disconnect the server (Secondary Replica) from the Object Explorer and close the query window.  Now change the property to Read-intent only.  Reconnect to the server and open a new query window and execute the same query.  Instead of results you will receive the following error:

Msg 978, Level 14, State 1, Line 1
The target database (‘AlwaysOnDB1′) is in an availability group and is currently accessible for connections when the application intent is set to read only. For more information about application intent, see SQL Server Books Online.

To circumvent this problem, you could use the Additional Connection Parameters tab when connecting to an instance of SQL Server 2012 with Management Studio. In the text box type:  ;ApplicationIntent=ReadOnly.  Your screen will look like this(you must include the semicolon):

image

When you connect and run the query everything works great.   I will be doing a SQL Lunch soon demonstrating this and showing how it will work with a .NET application.  Stay tuned.

If you have any questions or concerns regarding this post please feel free to email me at pleblanc@sqllunch.com

Talk to you soon,

Patrick LeBlanc

www.sqllunch.com

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating