In a previous blog post, I talked about the new SQL Server 2016 Availability Groups Load Balancing of Read-Only Replicas feature (I know that’s a mouthful but it’s how I understand the concept.) I explained how the precedence rules in defining how the read-only workload is balanced across multiple readable secondary replicas using nested parenthesis.
One of the most common implementations of Availability Groups is a 2-replica setup – one for primary and one for secondary. You can also have two possible options for the 2-replica setup – a failover clustered instance or a standalone instance as a primary. I’m a big fan of the failover clustered instance as a primary because you are providing both high availability and disaster recovery – high availability thru the failover clustered instance and disaster recovery thru the Availability Group. The decision to implement either one is always driven by cost. But let’s imagine that you can go beyond the 2-replica setup and implement readable secondary replicas. You can have a lot of different combinations on how to implement the new load balancing feature of read-only replicas. Which can also mean that you will have a lot of confusion trying to understand how you can make it work given your existing architecture.
Precedence Rules in Action
Suppose that you currently have a five (5) replica Availability Group setup that you plan to upgrade to SQL Server 2016. You use two of the replicas for readable secondary while the other two are just there for standby. With the increase in workload, you also plan to use the standby replicas for read-only purposes (after purchasing the additional license required, of course.)
Let’s see the possible combination of readable secondary replicas that you can use given this setup, highlighting the difference between the usage.
Default Behavior
This is the current behavior of Availability Group read-only routing – from SQL Server 2012 to SQL Server 2016.
ALTER AVAILABILITY GROUP SQL2016AG
MODIFY REPLICA ON
N'S1' WITH
(PRIMARY_ROLE
(
READ_ONLY_ROUTING_LIST=('S2','S3','S4','S5')
)
);
Regardless of the number of readable secondary replicas you include in the READ_ONLY_ROUTING_LIST, all read-only workloads will only be redirected to the secondary replica S2. Which, by the way, also means that you just threw away an Enterprise Edition license because you probably don’t even have the chance to use the secondary replica S5 unless three (3) out of the five (5) replicas are unavailable. I won’t dive deep into the licensing aspects of having secondary replicas S3 and S4 covered by software assurance of S1 and S2 because, technically, they’re just standby secondary replicas doing nothing. This is the reason why I wanted to talk about the cost implications of understanding the behavior of read-only routing.
Simply put, if you failover your Availability Group to S2 while S1 remains available, secondary replicas S3, S4 and S5 are all just standing by. If S1 goes offline and S2 becomes the new primary, that is the only time that S3 gets to function as a readable secondary replica and the only time that you would need a license for it. Of course, if you have a proper incident response process, you will probably bring S1 back online as soon as possible and move the Availability Group back to it, bringing S3 back as one of the standby replicas.
Nested Parenthesis #1: Using All of the Readable Secondary Replicas
This option is only available in SQL Server 2016. You can use the nested parenthesis to implement the new load balancing of read-only replicas feature based on your selected readable secondary replicas. Let’s start with using ALL of them. Pay attention to the use of the nested parenthesis. I’ve highlighted them for ease of identification.
ALTER AVAILABILITY GROUP SQL2016AG
MODIFY REPLICA ON
N'S1' WITH
(PRIMARY_ROLE
(
READ_ONLY_ROUTING_LIST=((
'S2','S3','S4','S5')
)
)
);
With the nested parenthesis, we are now telling the Availability Group to redirect all of the read-only workloads to all of the available secondary replicas defined in the READ_ONLY_ROUTING_LIST – S2, S3, S4 and S5 – using a round-robin algorithm. Which means we are now maximizing the use of all of our licenses because all of the readable secondary replicas are being used to service read-only requests.
If any of the readable secondary goes offline, the same algorithm works, redirecting the read-only workloads to all available readable secondary replicas.
Nested Parenthesis #2: Using Some of the Readable Secondary Replicas
Let’s say you only want to prioritize load balancing of the read-only workloads across a subset of all of the readable secondary replica. For example, you haven’t purchased the required licenses for the other two replicas or maybe the hardware resources are not as powerful as the rest. You can either do that by listing just two readable secondary replicas, like the syntax below.
Syntax #1
ALTER AVAILABILITY GROUP SQL2016AG
MODIFY REPLICA ON
N'S1' WITH
(PRIMARY_ROLE
(
READ_ONLY_ROUTING_LIST=('S2','S3')
)
);
Or you can use a nested parenthesis, like the syntax below.
Syntax #2
ALTER AVAILABILITY GROUP SQL2016AG
MODIFY REPLICA ON
N'S1' WITH
(PRIMARY_ROLE
(
READ_ONLY_ROUTING_LIST=((
'S2','S3')
,'S4','S5')
)
);
While the two syntax may have some similarities, the key difference lies in the use of the nested parenthesis. With Syntax #1, read-only workloads will only be redirected to S2 and S3, similar to the default behavior of S2 being the only one serving the read-only workloads until it becomes unavailable (S2 has to become unavailable before S3 can start serving read-only workloads; no load balancing between the two will occur unless you enclose them in a nested parenthesis.) Now, if both S2 and S3 become unavailable, the Availability Group will not redirect them to S4 and S5 even though they are still available. It’s basically the same as the default behavior but with limited readable secondary replicas in the READ_ONLY_ROUTING_LIST.
Syntax #2, on the other hand, includes S4 and S5. But because of the nested parenthesis, all read-only workloads are only redirected to S2 and S3, albeit load balanced between the two, unlike in Syntax #1. But what happens when both S2 and S3 become unavailable?
When both S2 and S3 become unavailable, Syntax #2 tells the Availability Group to go and redirect read-only workloads to S4 and only S4, not S5. It’s as if you’re running SQL Server 2012/2014 with the READ_ONLY_ROUTING_LIST containing only S4 and S5. The only time S5 gets utilized as a readable secondary replica is when all S2, S3 and S4 become unavailable. Again, similar to the default behavior of read-only routing.
Nested Parenthesis #3: Using Multiple Groups of Readable Secondary Replicas
Knowing how we can change the behavior of the read-only routing for load balancing using nested parenthesis, let’s take the previous scenario – the one using Syntax #2 – and group readable secondary replicas accordingly.
ALTER AVAILABILITY GROUP SQL2016AG
MODIFY REPLICA ON
N'S1' WITH
(PRIMARY_ROLE
(
READ_ONLY_ROUTING_LIST=((
'S2','S3')
,(
'S4','S5')
)
)
);
Pay attention to how the readable secondary replicas are grouped together. Because of the precedence with the first group – the one including S2 and S3 – all read-only workloads will be redirected and load balanced between those in the first group. If S2 becomes unavailable, only S3 will server the read-only workloads. Think of this as using the nested parenthesis but with only S2 and S3 in the READ_ONLY_ROUTING_LIST.
So, where does S4 and S5 come in? This is where the nested parenthesis comes in. Because they are defined in the second group of readable secondary replicas, S4 and S5 will start servicing read-only workloads – while being load balanced between them – if both S2 and S3 become unavailable.
This comes in very handy if S2 and S3 are primarily for high availability or maybe running on physical machines versus S4 and S5 being for disaster recovery or running on virtual machines.
NOTE: Only one level of nested parenthesis is supported in SQL Server 2016 as per this MSDN article. It may change in future versions.
Summary
While most people would look at this as simply syntactical differences, the way you implement them has a direct impact on your overall architecture and total cost of ownership. You could also look at it as the expensive US$50,000 nested parenthesis should you fail to consider how this new load balancing of read-only replicas feature behaves when designing and deploying your SQL Server 2016 Availability Group architecture.
Additional Resources
- Introducing the New SQL Server 2016 Availability Groups Load Balancing of Read-Only Replicas
- Configure Read-Only Routing for an Availability Group (SQL Server)
- SQL Server 2016 : availability groups and load balancing features
- Training: SQL Server Always On Availability Group: The Senior DBA’s Ultimate Field Guide
Schedule a Call