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
i have created 3 sql triggers using sql 2008 r2 64 bit. the backup server containing the unencrypted triggers has been lost. I do have the key used when creating the trigger. Is there a way to regain the code, like scripting it out or removing the encryption key just long enough to back it up and then re-apply the encryption?
In this article the Symmetric Key and Triple DES encryption is used.But if i go to SSMS then i can see ‘EncryptTestCert'(certificate used in this article) can be easily found in certificate folder and ‘TestTable'(symmetric key) can be found in symmetric keys folder in SSMS under that database. So anyone who can login to SSMS can easily decrypt database by using it. So how it can be prevented? Also any other methods?
I had try to encrypt password by using md5() but i got this error “‘MD5’ is not a recognized built-in function name. “.. what is the problem sir.. can you please help me..
hi.
My group has to do a real time project for our institute nd its based on library management. I have been given the task to handel the data base. other group members are doing the user end design using VB-2012. im using SQL server 2005. I ve created the loing in tabel but need to put password encryption. nd need to make the userid as the master key. can you plz help.
Hoping to get a early response.
Tank you.
if i want encrypt password at time of insertion then what is the way? can you give me a suggestion.
thank you
If you want to encrypt “Password” filed,
1) define the datatype varbinary(256) at the time of creation itself.
2) Create Db Master Key / Certificate and Symmetric Key
3) Insert by using ENCRYPTBYKEY(KEY_GUID(‘TestTableKey’),’givnPassword’)
when you want to validate the value need to be decript.
Awesome your blog like it
thanks pinal for you clear explanation. really it is helpfull
Thanks for this article. When I modify the existing view after encryption of a column, it gives error. any help …..? The view is given below:
CREATE VIEW [dbo].[v_Users_Pin]
AS
OPEN SYMMETRIC KEY sym_my_Key DECRYPTION
BY CERTIFICATE my_Certificate
SELECT
UserID
, Owner_No
, CONVERT(VARCHAR(8),DECRYPTBYKEY(PIN)) AS PIN
FROM dbo.Users
CLOSE SYMMETRIC KEY sym_my_Key
GO
—————————–
when i Parse it gives the following error: (it seems it is expecting SELECT work after “AS”)
Incorrect syntax near the keyword ‘OPEN’.
Thanks in advance
can someone tell me if I can have clustered indexed column and I wanted that to be encrypt it.
If I do a search on that column – will it work fine. if not please suggest an approach. thanks in advance.
Venkata, have you figured out solution for your problem? If so can you give me details how you did it?
Hi, nice information. How to deploy database which must contain encrypted stored procedures? How to create script which will deploy a database containing encrypted stored procedures?
Hi Pinal Dave,
I have 2 columns in one table, its datatype are numeric(18,0),datetime when i am going to encrypt these column i’m adding columns with same datatype it is giving error when the time of updation and I am tried with varbinary(256) also it is giving the same error.
The error is
” Argument data type numeric is invalid for argument 2 of EncryptByKey function “.
I am using SQL Server 2008r2 Enterprises edition . Please give me the solution for this how to encrypt the columns which i have mentioned. Is encryption will not work on these datatypes?
Thanks in advance……
Srinivasa Babu Doosa
My first foray into encryption of data. If I was to extract data and send as a flat or delimited text output to another party and they importeed data into a table which uses the dsame encryption keys and set up – would they be able to decrypt the data or shold i expect the system to berakdown somewhere along the line?
It’s very useful post. I have a query regarding my project. We have a portal where people can register and add their clients. Many users ask about the security of their client data. So even if we encrypt their password, the client data is still saved as clear text. What can be done the ensure our users about their data security.
Can we use it for binary data encryption & decryption?
Good Article. Thanks.
Good Article.But i want to whole database encrypt and decrypt.How to possible.
great tut, however can you make this so that the data is stored on the sql database but all the work is done via functions on a php script? i have this already but it stopped working when i wanted to edit the data so what should the format of the field be in tunrms of languiage coralation or what ever its called so that i can always edit if i need to as when it failed to update / edit a field eventually i had to drop the field and re make the field again the idea was originally to encypt members personal notes with a ssl certificate! and also there logged in userid session which i have done already please if anyone knows let me know :)
the post is very good however I have one question – is there a way to encrypt an int column instead of varchar. I did try to do that but I received an error “Argument data type int is invalid” The thing is that in my application I need to keep that column as int because I need to apply the sum function on it after decrypting it and I don’t want data inside that column to be exposed.
Thank you in advance for your help or suggestion
Hi Pinal
i’m implementing Database Mirroring SQL Server 2005.
The servers are diferent domain. i’m using certificates. but i have this error
USE master
CREATE MASTER KEY ENCRYPTION BY PASSWORD = ‘y0ur$ecUr3PAssw0rd’;
GO
Msg 15466, level 16, state 2, line 1
An error occurred during encryption
Hoping to get a early response. Thanks for help
Good article, still works in SQL2012.