SQL Server 2005 and SQL Server 2008 provide encryption as a new feature to protect data against hackers’ attacks. Hackers might be able to penetrate the database or tables, but owing to encryption they would not be able to understand the data or make use of it. Nowadays, it has become imperative to encrypt crucial security-related data while storing in the database as well as during transmission across a network between the client and the server.
Encryption hierarchy is marked by three-level security. These three levels provide different mechanisms for securing data across networks and local servers. Different levels of hierarchies allow multiple instances of services (e.g., SQL Server Services) to run on one physical server.
- Windows Level – Highest Level – Uses Windows DP API for encryption
- SQL Server Level – Moderate Level – Uses Services Master Key for encryption
- Database Level – Lower Level – Uses Database Master Key for encryption
There are two kinds of keys used in encryption:
- Symmetric Key – In Symmetric cryptography system, the sender and the receiver of a message share a single, common key that is used to encrypt and decrypt the message. This is relatively easy to implement, and both the sender and the receiver can encrypt or decrypt the messages.
- Asymmetric Key – Asymmetric cryptography, also known as Public-key cryptography, is a system in which the sender and the receiver of a message have a pair of cryptographic keys – a public key and a private key – to encrypt and decrypt the message. This is a relatively complex system where the sender can use his key to encrypt the message but he cannot decrypt it. The receiver, on the other hand, can use his key to decrypt the message but he cannot encrypt it. This intricacy has turned it into a resource-intensive process.
Yet another way to encrypt data is through certificates. A public key certificate is a digitally signed statement that binds the value of a public key to the identity of the person, device, or service that holds the corresponding private key. A Certification Authority (CA) issues and signs certifications.
Please create a sample database that we will be use for testing Encryption. There are two different kinds of encryptions available in SQL Server:
- Database Level – This level secures all the data in a database. However, every time data is written or read from database, the whole database needs to be decrypted. This is a very resource-intensive process and not a practical solution.
- Column (or Row) Level – This level of encryption is the most preferred method. Here, only columns containing important data should be encrypted; this will result in lower CPU load compared with the whole database level encryption. If a column is used as a primary key or used in comparison clauses (WHERE clauses, JOIN conditions) the database will have to decrypt the whole column to perform operations involving those columns.
Let’s go over a simple instance that demonstrates the encryption and the decryption process executed with Symmetric Key and Triple DES encryption algorithm.
/* Create Database */ USE master GO CREATE DATABASE EncryptTest ON PRIMARY ( NAME = N'EncryptTest', FILENAME = N'C:\EncryptTest.mdf') LOG ON ( NAME = N'EncryptTest_log', FILENAME = N'C:\EncryptTest_log.ldf') GO
First, let’s create a sample table and then populate it with sample data. We will now encrypt one of the two columns of the table.
/* Create table and insert data in the table */ USE EncryptTest GO CREATE TABLE TestTable (FirstCol INT, SecondCol VARCHAR(50)) GO INSERT INTO TestTable (FirstCol, SecondCol) SELECT 1,'First' UNION ALL SELECT 2,'Second' UNION ALL SELECT 3,'Third' UNION ALL SELECT 4,'Fourth' UNION ALL SELECT 5,'Fifth' GO /* Check the content of the TestTable */ USE EncryptTest GO SELECT * FROM TestTable GO
The preceding code will return the result depicted in the subsequent figure.

Every database can have one master key. Database master key is a symmetric key used to protect the private keys of certificates and asymmetric keys present in the database. It uses Triple DES algorithm together with user-provided password to encrypt the keys.
/* Create Database Master Key */ USE EncryptTest GO CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'SQLAuthority' GO
Certificates are used to safeguard encryption keys, which are used to encrypt data in the database. SQL Server 2005 has the capability to generate self-signed X.509 certificates.
/* Create Encryption Certificate */ USE EncryptTest GO CREATE CERTIFICATE EncryptTestCert WITH SUBJECT = 'SQLAuthority' GO
The symmetric key can be encrypted by using various options such as certificate, password, symmetric key, and asymmetric key. A number of different algorithms can be employed for encrypting key. The supported algorithms are DES, TRIPLE_DES, RC2, RC4, RC4_128, DESX, AES_128, AES_192, and AES_256.
/* Create Symmetric Key */ USE EncryptTest GO CREATE SYMMETRIC KEY TestTableKey WITH ALGORITHM = TRIPLE_DES ENCRYPTION BY CERTIFICATE EncryptTestCert GO
Now add a column of type varbinary to the original table, which will store the encrypted value for the SecondCol.
/* Encrypt Data using Key and Certificate Add Columns which will hold the encrypted data in binary */ USE EncryptTest GO ALTER TABLE TestTable ADD EncryptSecondCol VARBINARY(256) GO
Before the key is used, it needs to be decrypted using the same method that was used for encrypting it. In our example, we have used a certificate for encrypting the key. Because of the same reason, we are using the same certificate for opening the key and making it available for use. Subsequent to opening it and making it available for use, we can use the encryptkey function and store the encrypted values in the database, in the EncryptSecondCol column.
/* Update binary column with encrypted data created by certificate and key */ USE EncryptTest GO OPEN SYMMETRIC KEY TestTableKey DECRYPTION BY CERTIFICATE EncryptTestCert UPDATE TestTable SET EncryptSecondCol = ENCRYPTBYKEY(KEY_GUID('TestTableKey'),SecondCol) GO
We can drop the original SecondCol column, which we have now encrypted in the EncryptSecondCol column. If you do not want to drop the column, you can keep it for future comparison of the data when we decrypt the column.
/* DROP original column which was encrypted for protect the data */ USE EncryptTest GO ALTER TABLE TestTable DROP COLUMN SecondCol GO
We can run a SELECT query on our database and verify if our data in the table is well protected and hackers will not be able to make use of it even if they somehow manage to reach the data.
/* Check the content of the TestTable */ USE EncryptTest GO SELECT * FROM TestTable GO

Authorized user can use the decryptbykey function to retrieve the original data from the encrypted column. If Symmetric key is not open for decryption, it has to be decrypted using the same certificate that was used to encrypt it. An important point to bear in mind here is that the original column and the decrypted column should have the same data types. If their data types differ, incorrect values could be reproduced. In our case, we have used a VARCHAR data type for SecondCol and EncryptSecondCol.
/* Decrypt the data of the SecondCol */ USE EncryptTest GO OPEN SYMMETRIC KEY TestTableKey DECRYPTION BY CERTIFICATE EncryptTestCert SELECT CONVERT(VARCHAR(50),DECRYPTBYKEY(EncryptSecondCol)) AS DecryptSecondCol FROM TestTable GO
If you drop the database after the entire processing is complete, you do not have to worry about cleaning up the database. However, in real world on production servers, the database is not dropped. It is a good practice for developers to close the key after using it. If keys and certificates are used only once or their use is over, they can be dropped as well. Dropping a database will drop everything it contains – table, keys, certificates, all the data, to name a few.
/* Clean up database */ USE EncryptTest GO CLOSE SYMMETRIC KEY TestTableKey GO DROP SYMMETRIC KEY TestTableKey GO DROP CERTIFICATE EncryptTestCert GO DROP MASTER KEY GO USE [master] GO DROP DATABASE [EncryptTest] GO
Summary
Encryption is a very important security feature of SQL Server 2005. Long keys and asymmetric keys create unassailable, stronger encryption and stronger encryption uses lots of CPU to encrypt data. Stronger encryption is slower to process. When there is a huge amount of data to encrypt, it is suggested to encrypt it using a symmetric key. The same symmetric key can be encrypted further with an asymmetric key for additional protection, thereby adding the advantage of a stronger encryption. It is also recommended to compress data before encryption, as encrypted data cannot be compressed.
Reference : Pinal Dave (https://blog.sqlauthority.com)
154 Comments. Leave new
Hello Arun,
Only varbinary dataype can be encrypted was the limitation in SQL Server 2005. In SQL Server 2008, TDE support all data types.
Regards,
Pinal Dave
Great tutorial!
Hi Pinal Dave,
Thank you very much for the response.
Can you tell me, this is the way to call procedure for encryption type as below ?
EXEC @KEY= ‘TestTableKey’ , @CERTIFICATE =’EncryptTestCert’
GO
CREATE PROCEDURE spEncryption
@KEY VARCHAR(200),
@CERTIFICATE VARCHAR(200)
AS
BEGIN
DECLARE @dyKeyExecute varchar(2000)
SET @dyKeyExecute = ”
CREATE MASTER KEY ENCRYPTION
BY PASSWORD = ‘SQLAuthority’
SET @dyKeyExecute = ‘CREATE CERTIFICATE ‘ + @CERTIFICATE
SET @dyKeyExecute = @dyKeyExecute + ‘WITH SUBJECT = ‘ + ‘SQLAuthority’
EXEC (@dyKeyExecute)
SET @dyKeyExecute = ”
SET @dyKeyExecute = ‘CREATE SYMMETRIC KEY ‘ + @KEY
SET @dyKeyExecute = @dyKeyExecute + ‘WITH ALGORITHM = TRIPLE_DES ENCRYPTION
BY CERTIFICATE’ + @CERTIFICATE
EXEC (@dyKeyExecute)
SET @dyKeyExecute =”
SET @dyKeyExecute =’OPEN SYMMETRIC KEY’ + @KEY + ‘DECRYPTION BY CERTIFICATE’ + @CERTIFICATE
EXEC (@dyKeyExecute)
GO
SELECT CONVERT(VARCHAR(50),DECRYPTBYKEY(EncryptSecondCol)) AS DecryptSecondCol
FROM TestTable
/**drop the key**/
CLOSE SYMMETRIC KEY TestTableKey
GO
DROP SYMMETRIC KEY TestTableKey
GO
DROP CERTIFICATE EncryptTestCert
GO
DROP MASTER KEY
GO
END
Hi Pinal Dave,
I have written the dynamic sql for key, since I have a double, since it can be read from
SELECT * FROM sys.symmetric_keys
SELECT * FROM sys.certificates
so any one who knows this can access the data more over.. before executing the script , we are opening
OPEN SYMMETRIC KEY TestTableKey DECRYPTION
BY CERTIFICATE EncryptTestCert
so this key is visible to everyone who open’s the stored procedure .
Please guide me on this.
Thanks
Arun
how to add values to encrypted tables/columns
Hello Noreen,
There are various functions in SQL Server 2008 to encrypt and decript data. In this article I demonstrated the use of ENCRYPTBYKEY and DECRYPTBYKEY functions. There are more functions to encrypt by certificate and password.
Regards,
Pinal Dave
Hi Pinal,
i thought encryption and DEcryption is complecated after reading this article i am much comfortable usin Encryption and
DEcryption key
I have a situation where the data should go encrypted from one server to another
Server B should have the encrypted data and the data should be inserted from Server A using a SP to insert data to server B The Master Key,certificate and the Symmetric key has been created on Server B.I created a SSIS package which has a connection to serverB and run the following commands
OPEN SYMMETRIC KEY Keyvalue
DECRYPTION BY CERTIFICATE certvalue
and then run the following insert stmt on ServerA
INSERT INTO serverB.DB.dbo.tableB
(
MemID,
SSN)
SELECT ENCRYPTBYKEY(KEY_GUID(‘Keyvalue’),
CONVERT(VARBINARY(256), MemId)),
ENCRYPTBYKEY(KEY_GUID(‘Por_Mem_UytRfvg598’), CONVERT(VARBINARY(256), SSN))
from DB..tableA
but the encryption process wouldnt work .Please advice if this approach is right or any other way to inser the encrypted data to serverB and be able to decrypt successfully
I have a situation where the data should go encrypted from one server to another
Server B should have the encrypted data and the data should be inserted from Server A using a SP to insert data to server B The Master Key,certificate and the Symmetric key has been created on Server B.I created a SSIS package which has a connection to serverB and run the following commands
OPEN SYMMETRIC KEY Keyvalue
DECRYPTION BY CERTIFICATE certvalue
and then run the following insert stmt on ServerA
INSERT INTO serverB.DB.dbo.tableB
(
MemID,
SSN)
SELECT ENCRYPTBYKEY(KEY_GUID(‘Keyvalue’),
CONVERT(VARBINARY(256), MemId)),
ENCRYPTBYKEY(KEY_GUID(‘Keyvalue’), CONVERT(VARBINARY(256), SSN))
from DB..tableA
but the encryption process wouldnt work .Please advice if this approach is right or any other way to inser the encrypted data to serverB and be able to decrypt successfully
when i try to write in SQL2005 Management studio new query
USE EncryptTest
GO
CREATE MASTER KEY ENCRYPTION
BY PASSWORD = ‘SQLAuthority’
GO
Line 1: Incorrect syntax near ‘MASTER’.
why? what is wrong here?
and if option to active for this issue inside SQL2005 or it work without settings please advice
I want to distribute key to users! please tell me way to distribute key. Thanks you!
Pinal Dave
Hello
I am havibg problems restoring a db, that has been encypted. I noticed in object explorer my Db does not have a + next to it. I cannot restore or detach it. Not sure how to recover. Any help would be very much appriciated.
Thank you
Hello
Column (or Row) Level encryption is not a Transparent one not so?
i.e when using C# application the encryption must be done at the level of code not in sql server.
Is this true? if not how could i deal with encryted data column from C# application?
How can we encrypt the integer data in a column in sql server 2005.
Your tutorials are really very good
In sybase we have column level encrypt/ decrypt based on user role. Do we have the same in sqlserver 2008.
sybase code :-
grant decrypt on [ owner. ]tablename[(columnname [{,columname}])]
to user | group | role
Is it possible to encrypt the Numeric fields? I am using the sql server 2008 workgroup editon.
Hi ,
Thanks for the information. There is one more thing that, what if someone wants to change the Algorithm for master key creation ?
When you create a master key it automatically gets created with “T DES”. The syntax of creating a master key is:
CREATE MASTER KEY ENCRYPTION BY PASSWORD = ‘somepassword’
What if someone wants it to be “AES”. Can that be done. I have surfed through various resources but could not find anything.
Thanks and Regards
Gagan
Once we are done with the encrypthion, finally you are dropping the column. After that how I am going to insert a new record.
Hi Pinal,
Very Nice Article to start the encryption of column in the table.
Its my turn to work with encryption column in my project.
I search lot of articles but i found a good article from you.
Great Going…
Thanks
With Warm Regards
Sathish. P