Skip to content

Commit a8ea4b9

Browse files
committed
Create tde setup.sql
1 parent 4a2818e commit a8ea4b9

File tree

1 file changed

+51
-0
lines changed

1 file changed

+51
-0
lines changed

tde setup.sql

Lines changed: 51 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,51 @@
1+
--1. see toolbox\lab - tde encryption workshop 2014.sql
2+
--2. Note you should also backup the Service Master Key!!
3+
--3. Generate three strong passwords.
4+
--4. See important TODO to copy these files OFFSITE.
5+
USE master
6+
go
7+
CREATE MASTER KEY ENCRYPTION BY PASSWORD = '$123testpassword-VM1'; --The master database master key password 1
8+
GO
9+
--Proof it is now there
10+
SELECT * FROM sys.symmetric_keys where name = '##MS_DatabaseMasterKey##'
11+
GO
12+
CREATE CERTIFICATE TDECert_enctest_2012
13+
WITH SUBJECT = 'Testing TDE Cert'
14+
, START_DATE = '7/30/2019' --Today's Date
15+
, EXPIRY_DATE = '7/30/2099'; --Future Date
16+
GO
17+
--Proof it is now there
18+
SELECT * FROM sys.certificates where name = 'TDECert_enctest_2012'
19+
GO
20+
21+
--You must take backups for recovery of both the master DB master key and the cert.
22+
BACKUP MASTER KEY --each instance can have its own master key.
23+
TO FILE = 'E:\Program Files\Microsoft SQL Server\MSSQL14.SQL2K17\MSSQL\data\SQLMasterKey_20120314.key'
24+
ENCRYPTION BY PASSWORD = '$123testpassword' --This password is for the new master key backup file. The Master Key's password above is different. Password 2
25+
26+
BACKUP CERTIFICATE TDECert_enctest_2012
27+
TO FILE = 'E:\Program Files\Microsoft SQL Server\MSSQL14.SQL2K17\MSSQL\data\TestingTDEcert2014.cer'
28+
WITH PRIVATE KEY ( FILE = 'E:\Program Files\Microsoft SQL Server\MSSQL14.SQL2K17\MSSQL\data\TestingTDEcert2014.key' , --This is a new key file for the cert backup, NOT the same as the key for the MASTER KEY backup above.
29+
ENCRYPTION BY PASSWORD = '$12345testpassword123' ); --This password is for the cert backup's key file. The Master Key's password above is different. Password 3
30+
GO
31+
32+
USE [enctest] --In this case, enctest is the sample name of the database you want to encrypt with TDE.
33+
go
34+
--Create the key in the TDE database using the server cert we created earlier.
35+
CREATE DATABASE ENCRYPTION KEY
36+
WITH ALGORITHM = AES_256
37+
ENCRYPTION BY SERVER CERTIFICATE TDECert_enctest_2012
38+
GO
39+
--This actually enables TDE on the database. This begins an asynchronous encryption process, it will finish immediately and encrypt behind the scenes.
40+
ALTER DATABASE enctest SET ENCRYPTION ON
41+
GO
42+
43+
--Proof it is encrypted.
44+
SELECT [name], is_encrypted FROM sys.databases order by is_encrypted desc, name asc
45+
GO
46+
--Then check "tde status.sql" for encryption progress.
47+
48+
/* IMPORTANT:
49+
Copy the three passwords, MOVE the master key file, the cert backup, and the cert backup key, OFFSITE to a secure enterprise storage.
50+
DO NOT LOSE THEM. If you lose these files or passwords, you will NOT be able to restore/recover the database!!!
51+
*/

0 commit comments

Comments
 (0)