Configure isolated access for Hyperscale named replicas
Applies to: Azure SQL Database
This article describes the procedure to grant access to an Azure SQL Database Hyperscale named replica without granting access to the primary replica or other named replicas. This scenario allows resource and security isolation of a named replica - as the named replica will be running using its own compute node - and it is useful whenever isolated read-only access to an Azure SQL Hyperscale database is needed. Isolated, in this context, means that CPU and memory are not shared between the primary and the named replica, queries running on the named replica do not use compute resources of the primary or of any other replicas, and principals accessing the named replica cannot access other replicas, including the primary.
Note
Microsoft Entra ID was previously known as Azure Active Directory (Azure AD).
Create a login on the primary server
In the master
database on the logical server hosting the primary database, execute the following to create a new login.
Use your own strong and unique password, replacing strong_password_here
with your strong password.
CREATE LOGIN [third-party-login] WITH PASSWORD = 'strong_password_here';
Retrieve the SID hexadecimal value for the created login from the sys.sql_logins
system view:
SELECT SID FROM sys.sql_logins WHERE name = 'third-party-login';
Disable the login. This prevents this login from accessing any database on the server hosting the primary replica.
ALTER LOGIN [third-party-login] DISABLE;
Create a user in the primary read-write database
Once the login has been created, connect to the primary read-write replica of your database, for example WideWorldImporters (you can find a sample script to restore it here: Restore Database in Azure SQL) and create a database user for that login:
CREATE USER [third-party-user] FROM LOGIN [third-party-login];
As an optional step, once the database user has been created, you can drop the server login created in the previous step if there are concerns about the login getting re-enabled in any way. Connect to the master
database on the logical server hosting the primary database, and execute the following sample scripts:
DROP LOGIN [third-party-login];
Create a named replica on a different logical server
Create a new Azure SQL logical server that to be used to isolate access to the named replica. Follow the instructions available at Create and manage servers and single databases in Azure SQL Database. To create a named replica, this server must be in the same Azure region as the server hosting the primary replica.
In the following sample, replace strong_password_here
with your strong password. For example, using Azure CLI:
az sql server create -g MyResourceGroup -n MyNamedReplicaServer -l MyLocation --admin-user MyAdminUser --admin-password strong_password_here
Then, create a named replica for the primary database on this server. For example, using Azure CLI:
az sql db replica create -g MyResourceGroup -n WideWorldImporters -s MyPrimaryServer --secondary-type Named --partner-database WideWorldImporters_NR --partner-server MyNamedReplicaServer
Create a login on the named replica server
Connect to the master
database on the logical server hosting the named replica, created in the previous step. Replace strong_password_here
with your strong password. Add the login using the SID retrieved from the primary replica:
CREATE LOGIN [third-party-login] WITH PASSWORD = 'strong_password_here', sid = 0x0...1234;
At this point, users and applications using third-party-login
or bob@contoso.com
can connect to the named replica, but not to the primary replica.
Grant object-level permissions within the database
Once you have set up login authentication as described, you can use regular GRANT
, DENY
and REVOKE
statements to manage authorization, or object-level permissions within the database. In these statements, reference the name of the user you created in the database, or a database role that includes this user as a member. Remember to execute these commands on the primary replica. The changes propagate to all secondary replicas, but they will only be effective on the named replica where the server-level login was created.
Remember that by default a newly created user has a minimal set of permissions granted (for example, it cannot access any user tables). If you want to allow third-party-user
or bob@contoso.com
to read data in a table, you need to explicitly grant the SELECT
permission:
GRANT SELECT ON [Application].[Cities] to [third-party-user];
As an alternative to granting permissions individually on every table, you can add the user to the db_datareaders
database role to allow read access to all tables, or you can use schemas to allow access to all existing and new tables in a schema.
Test access
You can test this configuration by using any client tool and attempt to connect to the primary and the named replica. For example, using sqlcmd
, you can try to connect to the primary replica using the third-party-login
user. Replace strong_password_here
with your strong password.
sqlcmd -S MyPrimaryServer.database.chinacloudapi.cn -U third-party-login -P strong_password_here -d WideWorldImporters
This will result in an error as the user is not allowed to connect to the server:
Sqlcmd: Error: Microsoft ODBC Driver 13 for SQL Server : Login failed for user 'third-party-login'. Reason: The account is disabled.
The attempt to connect to the named replica succeeds. Replace strong_password_here
with your strong password.
sqlcmd -S MyNamedReplicaServer.database.chinacloudapi.cn -U third-party-login -P strong_password_here -d WideWorldImporters_NR
No errors are returned, and queries can be executed on the named replica as allowed by granted object-level permissions.
Related content
- Azure SQL logical Servers, see What is a server in Azure SQL Database?
- Managing database access and logins, see SQL Database security: Manage database access and login security.
- Database engine permissions, see Permissions.
- Granting object permissions, see GRANT Object Permissions.