Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server
Azure SQL Database
Azure SQL Managed Instance
Azure Synapse Analytics
Analytics Platform System (PDW)
SQL database in Microsoft Fabric
Creates a database master key in the database.
Important
Transact-SQL syntax conventions
CREATE MASTER KEY [ ENCRYPTION BY PASSWORD ='password' ]
[ ; ]
The password that is used to encrypt the master key in the database. password must meet the Windows password policy requirements of the computer that is running the instance of SQL Server. password is optional in SQL Database and Azure Synapse Analytics.
The database master key is a symmetric key used to protect the private keys of certificates and asymmetric keys that are present in the database and secrets in database scoped credentials. When it is created, the master key is encrypted by using the AES_256 algorithm and a user-supplied password. In SQL Server 2008 (10.0.x) and SQL Server 2008 R2 (10.50.x), the Triple DES algorithm is used. To enable the automatic decryption of the master key, a copy of the key is encrypted by using the service master key and stored in both the database and in master
. Typically, the copy stored in master
is silently updated whenever the master key is changed. This default can be changed by using the DROP ENCRYPTION BY SERVICE MASTER KEY option of ALTER MASTER KEY. A master key that isn't encrypted by the service master key must be opened by using the OPEN MASTER KEY statement and a password.
The is_master_key_encrypted_by_server
column of the sys.databases
catalog view in master
indicates whether the database master key is encrypted by the service master key.
Information about the database master key is visible in the sys.symmetric_keys
catalog view.
For SQL Server and Parallel Data Warehouse, the master key is typically protected by the service master key and at least one password. In case of the database being physically moved to a different server (log shipping, restoring backup, etc.), the database will contain a copy of the master key encrypted by the original server service master key (unless this encryption was explicitly removed using ALTER MASTER KEY DDL
), and a copy of it encrypted by each password specified during either CREATE MASTER KEY
or subsequent ALTER MASTER KEY DDL
operations. In order to recover the master key, and all the data encrypted using the master key as the root in the key hierarchy after the database has been moved, the user will have either use OPEN MASTER KEY
statement using one of the passwords used to protect the master key, restore a backup of the master key, or restore a backup of the original service master key on the new server.
For SQL Database and Azure Synapse Analytics, the password protection isn't considered to be a safety mechanism to prevent a data loss scenario in situations where the database may be moved from one server to another, as the service master key protection on the master key is managed by Microsoft Azure platform. Therefore, the master key password is optional in SQL Database and Azure Synapse Analytics.
For SQL Database, the database master key can be created automatically to protect the secrets in database scoped credentials used for auditing and other features that require a database scoped credential to authenticate to an external resource, like an Azure Storage account. The master key is created with a strong randomly selected password. Users can't create the master key on a logical master
database. The master key password is unknown to Microsoft and not discoverable after creation. For this reason, creating a database master key before creating a database scoped credential is recommended.
The service master key and database master keys are protected by using the AES-256 algorithm.
Requires CONTROL permission on the database.
Use the following example to create a database master key in a database. The key is encrypted using a password.
CREATE MASTER KEY ENCRYPTION BY PASSWORD = '<strong password>';
GO
Verify the presence of the new key, ##MS_DatabaseMasterKey##
:
SELECT * FROM sys.symmetric_keys;
GO
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register today