This notebook demonstrates the use of Azure Key Vault to enable TDE on a SQL Server 2019 Standard Edition database using EKM.
Pre-requisities
pip install --user azure-cli
az login
az account set --subscription <-subscription id->
az ad sp create-for-rbac -n sqlaadtde --skip-assignment
{"appId": "<-guid->",
"displayName": "sqlaadtde",
"name": "http://sqlaadtde",
"password": "<-guid->",
"tenant": "<-guid->"}
# Create a new resource group
az group create -n "SQLTDEResourceGroup" -l "West US"
# Register the Key Vault resource provider
az provider register -n Microsoft.KeyVault
az keyvault create --name "SQLStandardKeyVault" --resource-group "SQLTDEResourceGroup" --location "West US"
5. Register the Azure AD principl with AKV
# Register the AAD principal
az keyvault set-policy --name "SQLStandardKeyVault" --spn --key-permissions get list wrapKey unwrapKey --verbose
Details about the scenario is available here.
Download and install the SQL Server Connector. (This should be done by the administrator of the SQL Server computer.) By default, the connector installs at C:\Program Files\SQL Server Connector for Microsoft Azure Key Vault. This location can be changed during setup. (If changed, adjust the scripts below.)
There is no interface for the Connector, but if it is installed successfully, the Microsoft.AzureKeyVaultService.EKM.dll is installed on the machine. This is the cryptographic EKM provider DLL that needs to be registered with SQL Server by using the CREATE CRYPTOGRAPHIC PROVIDER statement.
USE master;
GO
sp_configure 'show advanced options', 1;
GO
RECONFIGURE WITH OVERRIDE;
GO
-- Enable EKM provider
sp_configure 'EKM provider enabled', 1;
GO
RECONFIGURE WITH OVERRIDE;
GO
-- Create a cryptographic provider, using the SQL Server Connector
-- which is an EKM provider for the Azure Key Vault. This example uses
-- the name AzureKeyVault_EKM_Prov.
CREATE CRYPTOGRAPHIC PROVIDER AzureKeyVault_EKM_Prov
FROM FILE = 'C:\Program Files\SQL Server Connector for Microsoft Azure Key Vault\Microsoft.AzureKeyVaultService.EKM.dll';
GO
The IDENTITY here is the name of your Azure key vault.
The SECRET here is your AAD Client ID (with the hyphens removed) and your AAD Client Secret concatenanted together
You will need to create a "New Client Secret" for your Azure AD app registration i.e. sqlaadtde, which was created above. See steps here.
CREATE CREDENTIAL Azure_EKM_TDE_cred
WITH IDENTITY = 'SQLStandardKeyVault', -- for global Azure
-- WITH IDENTITY = 'ContosoDevKeyVault.vault.usgovcloudapi.net', -- for Azure Government
-- WITH IDENTITY = 'ContosoDevKeyVault.vault.azure.cn', -- for Azure China 21Vianet
-- WITH IDENTITY = 'ContosoDevKeyVault.vault.microsoftazure.de', -- for Azure Germany
SECRET = '<combination of AAD Client ID without hyphens and AAD Client Secret>'
FOR CRYPTOGRAPHIC PROVIDER AzureKeyVault_EKM_Prov
You will need to first create a Key in Azure Key Vault which can be used to create the Asymmetric Key in SQL Server
# Create a software-protected key
az keyvault key create --vault-name "SQLStandardKeyVault" --name "SQLTDEKey" --protection software
CREATE ASYMMETRIC KEY dbAKV_Key
FROM PROVIDER [AzureKeyVault_EKM_Prov]
WITH PROVIDER_KEY_NAME = 'SQLTDEKey', -- This is the KEY that was created in the Azure Key Vault
CREATION_DISPOSITION = OPEN_EXISTING;
USE master;
-- Create a SQL Server login associated with the asymmetric key
-- for the Database engine to use when it loads a database
-- encrypted by TDE.
CREATE LOGIN TDE_Login
FROM ASYMMETRIC KEY dbAKV_Key;
GO
-- Alter the TDE Login to add the credential for use by the
-- Database Engine to access the key vault
ALTER LOGIN TDE_Login
ADD CREDENTIAL Azure_EKM_TDE_cred ;
GO
CREATE DATABASE dbAKVTDE;
GO
USE dbAKVTDE;
GO
CREATE DATABASE ENCRYPTION KEY
WITH ALGORITHM = AES_256
ENCRYPTION BY SERVER ASYMMETRIC KEY dbAKV_Key; -- Use the key created above
GO
-- Alter the database to enable transparent data encryption.
ALTER DATABASE dbAKVTDE
SET ENCRYPTION ON;
GO
USE MASTER
SELECT name,provider_type, algorithm_desc FROM sys.asymmetric_keys
-- Check which databases are encrypted using TDE
SELECT SERVERPROPERTY('Edition') as [Edition],d.name, dek.encryption_scan_state_desc, dek.encryptor_type
FROM sys.dm_database_encryption_keys AS dek
JOIN sys.databases AS d
ON dek.database_id = d.database_id;
name | provider_type | algorithm_desc |
---|---|---|
dbAKV_Key | CRYPTOGRAPHIC PROVIDER | RSA_2048 |
Edition | name | encryption_scan_state_desc | encryptor_type |
---|---|---|---|
Standard Edition (64-bit) | tempdb | COMPLETE | ASYMMETRIC KEY |
Standard Edition (64-bit) | dbTDE | COMPLETE | CERTIFICATE |
Standard Edition (64-bit) | dbAKVTDE | COMPLETE | ASYMMETRIC KEY |
To ensure quick key recovery and be able to access your data outside of Azure, we recommend the following best practices:
a. Create your encryption key locally on a local HSM device. (Make sure this is an asymmetric, RSA 2048 key so it's is supported by SQL Server.)
b. Import the encryption key to Azure Key Vault. See the steps in this article on how to do that.
c. Before using the key in Azure Key Vault for the first time, take an Azure Key Vault key backup. Learn more about the Backup-AzureKeyVaultKey command.
Whenever any changes are made to the key (for example add ACLs, add tags, add key attributes), be sure to take another Azure Key Vault key backup.
There are two types of keys you can generate in Azure Key Vault that will work with SQL Server. Both are asymmetric 2048-bit RSA keys.
Software-protected: Processed in software and encrypted at rest. Operations on software-protected keys occur on Azure Virtual Machines. Recommended for keys not used in a production deployment.
HSM-protected: Created and protected by a hardware security module (HSM) for additional security.
For common troubleshooting and maintenance of the SQL Server Connector, please refer to this article.