Events
Mar 31, 11 PM - Apr 2, 11 PM
The ultimate SQL, Power BI, Fabric, and AI community-led event. March 31 - April 2. Use code MSCUST for a $150 discount. Prices go up Feb 11th.
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
This topic describes how to back up a database master key in SQL Server by using Transact-SQL. The database master key is used to encrypt other keys and certificates inside a database. If it's deleted or corrupted, SQL Server may be unable to decrypt those keys, and the data encrypted using them will be effectively lost. For this reason, you should back up the database master key and store the backup in a secure off-site location.
The master key must be open and, therefore, decrypted before it's backed up. If it's encrypted with the service master key, the master key doesn't have to be explicitly opened. But if the master key is encrypted only with a password, it must be explicitly opened.
We recommend that you back up the master key as soon as it's created, and store the backup in a secure, off-site location.
Requires CONTROL permission on the database.
In SQL Server Management Studio, connect to the SQL Server instance containing the database master key you wish to back up.
Choose a password that will be used to encrypt the database master key on the backup medium. This password is subject to complexity checks.
Obtain a removable backup medium for storing a copy of the backed-up key.
Identify an NTFS directory in which to create the backup of the key. This is where you'll create the file specified in the next step. The directory should be protected with highly restrictive access control lists (ACLs).
In Object Explorer, connect to an instance of Database Engine.
On the Standard bar, click New Query.
Copy and paste the following example into the query window and click Execute.
-- Creates a backup of the "AdventureWorks2022" master key. Because this master key is not encrypted by the service master key, a password must be specified when it is opened.
USE AdventureWorks2022;
GO
OPEN MASTER KEY DECRYPTION BY PASSWORD = 'sfj5300osdVdgwdfkli7';
BACKUP MASTER KEY TO FILE = 'c:\temp\exportedmasterkey'
ENCRYPTION BY PASSWORD = 'sd092735kjn$&adsg';
GO
Note
The file path to the key and the key's password (if it exists) will be different than what is indicated above. Please make sure that both are specific to your server and key set-up.
Copy the file to the backup medium and verify the copy.
Store the backup in a secure, off-site location.
For more information, see OPEN MASTER KEY (Transact-SQL) and BACKUP MASTER KEY (Transact-SQL).
Events
Mar 31, 11 PM - Apr 2, 11 PM
The ultimate SQL, Power BI, Fabric, and AI community-led event. March 31 - April 2. Use code MSCUST for a $150 discount. Prices go up Feb 11th.
Register todayTraining
Module
Back up and restore your Azure SQL database - Training
Learn how to protect the data in your Azure SQL database and recover from data loss or corruption with backup and restore.
Certification
Microsoft Certified: Azure Database Administrator Associate - Certifications
Administer an SQL Server database infrastructure for cloud, on-premises and hybrid relational databases using the Microsoft PaaS relational database offerings.