Blog Post

Azure Database Support Blog
6 MIN READ

Setting up SQL Managed Instance Link to an Availability Group (Updated September 2025)

SamGarth's avatar
SamGarth
Icon for Microsoft rankMicrosoft
Jan 10, 2025

We will go through an example to ensure an AG failover does not break Managed Instance Link.

On a recent case, a customer was trying to set up SQL Managed Instance Link to partner with an on premise Always On Availability Group (AG). Using the public documentation will work, but there are some differences required to ensure a failover does not break the connection. 

Please note that Managed Instance Link can only be created with an availability group with a single database.

This post will be using steps from the following documents.

Prepare your environment for a link - Azure SQL Managed Instance

Configure link with scripts - Azure SQL Managed Instance

The steps to set this up are below

  • Create a database master key on the AG nodes
  • Enabling trace flags on the AG nodes (Optional)
  • Testing network connectivity between SQL Managed Instance and the AG
  • Create certificates on the AG nodes
  • Import AG certificate public keys to SQL Managed Instance
  • Import the certificate public key of the SQL Managed Instance to AG nodes
  • Import Azure-trusted root certificate authority keys to AG nodes
  • Alter the mirroring endpoint on AG nodes
  • Create a distributed availability group on AG
  • Set up the managed Instance Link

Create a database master key

Firstly, a master encryption key is required on all nodes of the AG if it does not already exist.

The script below will not return any rows if it does not exist.

-- Run on SQL Server
USE master;
GO
SELECT * FROM sys.symmetric_keys WHERE name LIKE '%DatabaseMasterKey%';

If no rows are returned, the following query can be used. Keep a note of the passwords in a confidential and secure place.

-- Run on SQL Server
-- Create a master key
USE master;
GO
CREATE MASTER KEY ENCRYPTION BY PASSWORD = '<strong_password>';

 

Enabling trace flags on AG nodes (Optional)

To optimise the performance of the link, we recommend enabling the trace flags T1800 and T9567 on all nodes.

Instructions on this are here and will require a restart of the service.


Testing network connectivity between SQL Managed Instance and the AG

Instructions on how to run the connectivity tests can be found here, and can be done by SSMS GUI or T-SQL.

For these tests, the SQL Managed Instance will need to be able to connect to the Mirror endpoint using the IP of the availability group. The SQL Managed Instance IPs can can change (for example during maintenance). For that reason NSG and firewall rules should allow access to ports 5022 and 11000-11999 for the whole subnet range of the SQL Managed Instance.


Create certificates on AG nodes

The below query will need to be run on all AG nodes. Pay particular attention to the @cert_expiry_date variable to ensure it is a date in the future. It will need to be replaced after expiry.

-- Create the SQL Server certificate for the instance link
USE MASTER

-- Customize SQL Server certificate expiration date by adjusting the date below
DECLARE @cert_expiry_date AS varchar(max)='03/30/2025'

-- Build the query to generate the certificate
DECLARE @sqlserver_certificate_name NVARCHAR(MAX) = N'Cert_' + @@servername  + N'_endpoint'
DECLARE @sqlserver_certificate_subject NVARCHAR(MAX) = N'Certificate for ' + @sqlserver_certificate_name
DECLARE @create_sqlserver_certificate_command NVARCHAR(MAX) = N'CREATE CERTIFICATE [' + @sqlserver_certificate_name + '] ' + char (13) +
'    WITH SUBJECT = ''' + @sqlserver_certificate_subject + ''',' + char (13) +
'    EXPIRY_DATE = '''+ @cert_expiry_date + ''''+ char (13)
IF NOT EXISTS (SELECT name from sys.certificates WHERE name = @sqlserver_certificate_name)
BEGIN
    PRINT (@create_sqlserver_certificate_command)
    -- Execute the query to create SQL Server certificate for the instance link
    EXEC sp_executesql @stmt = @create_sqlserver_certificate_command
END
ELSE
    PRINT 'Certificate ' + @sqlserver_certificate_name + ' already exists.'
GO


Import AG certificate public keys to SQL Managed Instance

The public keys of the AG certificates need to be imported into the SQL Managed Instance. 

The below query will return the data required for the next step.

-- Run on SQL Server
-- Show the name and the public key of generated SQL Server certificate
USE MASTER
GO
DECLARE @sqlserver_certificate_name NVARCHAR(MAX) = N'Cert_' + @@servername  + N'_endpoint'
DECLARE @PUBLICKEYENC VARBINARY(MAX) = CERTENCODED(CERT_ID(@sqlserver_certificate_name));
SELECT @sqlserver_certificate_name as 'SQLServerCertName'
SELECT @PUBLICKEYENC AS SQLServerPublicKey;

Example result

The next step will need to be run in PowerShell and can be run through Azure Cloud Shell.

Below is an example script to log in to Azure.

# Run in Azure Cloud Shell (select PowerShell console)

# Enter your Azure subscription ID
$SubscriptionID = "<subscriptionid>"

# Login to Azure and select subscription ID
if ((Get-AzContext ) -eq $null)
{
    echo "Logging to Azure subscription"
    Login-AzAccount
}
Select-AzSubscription -SubscriptionName $SubscriptionID

Replace the values of $CertificateName, $PublicKeyEncoded and $ManagedInstanceName and then run this.

# Run in Azure Cloud Shell (select PowerShell console)
# ===============================================================================
# POWERSHELL SCRIPT TO IMPORT SQL SERVER PUBLIC CERTIFICATE TO SQL MANAGED INSTANCE
# ===== Enter user variables here ====

# Enter the name for the server SQLServerCertName certificate – for example, "Cert_sqlserver1_endpoint"
$CertificateName = "<sqlservercertname>"

# Insert the certificate public key blob that you got from SQL Server – for example, "0x1234567..."
$PublicKeyEncoded = "<sqlserverpublickey>"

# Enter your managed instance short name – for example, "sqlmi"
$ManagedInstanceName = "<managedinstancename>"

# ==== Do not customize the below cmdlets====

# Find out the resource group name
$ResourceGroup = (Get-AzSqlInstance -InstanceName $ManagedInstanceName).ResourceGroupName

# Upload the public key of the authentication certificate from SQL Server to Azure.
New-AzSqlInstanceServerTrustCertificate -ResourceGroupName $ResourceGroup -InstanceName $ManagedInstanceName -Name $CertificateName -PublicKey $PublicKeyEncoded

Repeat this step for all AG node values.

 

Import the certificate public key of SQL Managed Instance to AG nodes

Using the same PowerShell session, run this script to get the public key of the SQL Managed Instance certificate, replacing the value of the variable $ManagedInstanceName.

# Run in Azure Cloud Shell (select PowerShell console)
# ===============================================================================
# POWERSHELL SCRIPT TO EXPORT MANAGED INSTANCE PUBLIC CERTIFICATE
# ===== Enter user variables here ====

# Enter your managed instance short name – for example, "sqlmi"
$ManagedInstanceName = "<managedinstancename>"

# ==== Do not customize the following cmdlet ====

# Find out the resource group name
$ResourceGroup = (Get-AzSqlInstance -InstanceName $ManagedInstanceName).ResourceGroupName

# Fetch the public key of the authentication certificate from Managed Instance. Outputs a binary key in the property PublicKey.
Get-AzSqlInstanceEndpointCertificate -ResourceGroupName $ResourceGroup -InstanceName $ManagedInstanceName -EndpointType "DATABASE_MIRRORING" | out-string</managedinstancename>

 

On all nodes of the AG run the following query, replacing the certificate name and the value of the PublicKey with the output from the previous step.

-- Run on SQL Server
USE MASTER
CREATE CERTIFICATE [<managedinstancefqdn>]
FROM BINARY = <publickey></publickey></managedinstancefqdn>

 

Import Azure-trusted root certificate authority keys to AG nodes

Use the steps here to import the Microsoft PKI root-authority certificate and DigiCert PKI root-authority certificate onto all nodes of the AG.

 

Alter the mirroring endpoint on AG nodes

The mirroring endpoint on the AG nodes will also need to be updated to allow the Managed Instance to authenticate with the AG using the newly created certificate.

This can be done by navigating to Server Objects > Endpoints > Database Mirroring. Right click on the endpoint and select Script Endpoint as > CREATE To > New Query Editor Window.

Change CREATE ENDPOINT to ALTER ENDPOINT and add this command after AUTHENTICATION = WINDOWS NEGOTIATE CERTIFICATE, changing the cert_name value.

CERTIFICATE [cert_name]

Once updated, execute the query.

 

For multiple Availability groups on the same instance, the next section would need to be repeated for each one.


Create a distributed availability group on the AG (running against the primary server)

Use this script to set up the distributed availability group, updating the sections in angle brackets (<>). 

The SQLServerIP will need to be the IP of the listener of the availability group.

-- Run on SQL Server
-- Create a distributed availability group for the availability group and database
-- ManagedInstanceName example: 'sqlmi1'
-- ManagedInstanceFQDN example: 'sqlmi1.73d19f36a420a.database.windows.net'
USE MASTER
CREATE AVAILABILITY GROUP [<dagname>]
WITH (DISTRIBUTED) 
    AVAILABILITY GROUP ON  
    N'<agnameonsqlserver>' WITH 
    (
      LISTENER_URL = 'TCP://<sqlserverip>:<endpointport>',
      AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT,
      FAILOVER_MODE = MANUAL,
      SEEDING_MODE = AUTOMATIC,
      SESSION_TIMEOUT = 20
    ),
    N'<agnameonsqlmi>' WITH
    (
      LISTENER_URL = 'tcp://<managedinstancefqdn>:5022;Server=[<managedinstancename>]',
      AVAILABILITY_MODE = ASYNCHRONOUS_COMMIT,
      FAILOVER_MODE = MANUAL,
      SEEDING_MODE = AUTOMATIC
    );
GO</managedinstancename></managedinstancefqdn></agnameonsqlmi></endpointport></sqlserverip></agnameonsqlserver></dagname>


Set up the managed Instance Link

The final step is to set up the link, the script for this is here.

Please ensure that the $SQLServerIP is the IP of the AG listener and not the IP of the primary node.

Once this is executed, the MI Link should be up and running and failing over to another node on the AG will not stop MI Link from syncing.

Disclaimer
Please note that products and options presented in this article are subject to change. This article reflects MI Link and the documentation in September 2025.

 

I hope this article was helpful for you, please feel free to share your feedback in the comments section. 

Updated Sep 19, 2025
Version 2.0

4 Comments

  • PaulW1290's avatar
    PaulW1290
    Copper Contributor

    Does this solution solve the issue of not being able to set up an instance link to an on-prem AG Group containing multiple databases? So far I have only read that setting up instance link with on-premises can only be done if the on-prem AG Group only contains a single database, and not multiple databases?

     

    • SamGarth's avatar
      SamGarth
      Icon for Microsoft rankMicrosoft

      Hi Paul, thank you for the question. This post has been updated with further information. It is still only supported with one database in the availability group.

  • mario_lottering's avatar
    mario_lottering
    Copper Contributor

    This guide is out of date.. Probably needs to look like this or something similar:

    New-AzSqlInstanceLink -InstanceName $ManagedInstanceName -Name $DAGName -PartnerAvailabilityGroupName $AGNameOnSQLServer -ResourceGroupName $ResourceGroup -InstanceAvailabilityGroupName $AGNameOnSQLMI -PartnerEndpoint $SourceIP -Database $DatabaseName

    • SamGarth's avatar
      SamGarth
      Icon for Microsoft rankMicrosoft

      Hi Mario, thank you for the post. I have updated the post to reflect the current version on Azure Cloud Shell.