Encryption 101

Encryption 101

Rate This
  • Comments 3

With the release of SQL Server 2005 comes a plethora of new security related features.  Over time we will cover these in detail.  To start, let's look at the world of encryption.

When it comes to protecting data we can take a mile high view of this problem and determine that we need to protect it while its in trasit (over the wire) and when its at rest (while stored on a physcial disk or memory).  Some of you have probably read various stories about company laptop's being stolen that contain large amounts of sensitive information.  This is a great example of the need to protect sensitive data stored at rest.

In previous versions of SQL Server (pre-2005), the server had limited features out of the box to protect data while in transit and had no native support to encrypt data within the database.  (There are some third party vendors that added this type of functionality in SQL 2000).

Before we go into details on encryption, we should first go through some of the key concepts in this space.  If you can already define words like "symmetric key" and "certificate", then you can skip ahead to the "Protecting data while in transit" section later in this post.

Encryption Primer:

Let's say I have a table of customer credit card numbers and I want to encrypt the credit card number column.  In order to encrypt this text I need three things: an encryption key, an algorithm, and the actual text I want to encrypt.  When we take the text and key and run the algorithm on it, we end up with what is known as ciphertext (the encrypted data). 

"4428-0123-4567-8910" --Now becomes--> 0x01238EB28401AC0283...

There are two types of keys we will talk about in this blog: Symmetric and Asymmetric.

A symmetric key is a single key that is used for both encrypting and decrypting data.  So if I wanted you to be able to decrypt my credit card list, I would simply give you the same symmetric key I used when I encrypted it.  Now al you have to do is pass the encrypted ciphertext and key into the algorithm and voila you have the original plain text. Symmetric key encryption and decryption is fast relative to asymmetric keys, however, there are some important points to remember when using symmetric keys.  What if as I was giving you the key someone saw the key and copied it?  Now everytime I send you the encrypted credit card list, the attacker who has made a copy of the symmetric key can easily decrypt it and now we have a serious problem.  So when we use symmetric key encryption we absolutely must protect the keys or else all of this encryption business is irrelevant.  In SQL Server 2005 we do protect symmetric keys in two ways, via password and via encryption by another key.  I will explain more in the "Protecting data while at rest" section.

An Asymetric key is essentially two keys: A public key and a private key.   Both of these keys are mathematically similar so when something is encrypted using my public key I can decrypt it using my private key and vise versa.  This allows me to give everyone in the world my public key and I can have them send me encrypted messages that can only be decrypted using my private key (which I don't give out to anyone and lock it under 100 feet of lead and cement, a couple guard dogs, boobie-traps, land-mines and whatever else I can use to protect it).  This behavior works well for the web.  When you request a connection over HTTPS: you essentially are requesting their public key to be used in decrypting the contents on their web pages.

A certificate is an asymmetric key with some extra metadata like an expiration date, the name of the certificate authroity that issued the certificate, etc.  Having a third-party certificate authority issue you a certificate can be important depending on the size of your organization and how you are using the certificate.  It basically gives users more confidence that the data they are receiving and sending to someone is actually coming from that person and not some impersonator.

The amount of algorithms available depend on which version of the operating system you are using.  Each algorithm has pros and cons and if you are interesting in learning more about these, there is a ton of information on the web for further study.

 XPSP2 supports DES, 3DES, RC2, RC4, RSA

Windows 2003 server supports DES, 3DES, AES128, AES192, AES256, RC2, RC4, RSA

I am just scratching the surface when it comes to introducing these topics, if you are interested there are bunch of good books out there that describe cryptography in great detail.

Protecting data while in transit in SQL Server 2005:

Using the SQL Server Computer Manager you can set your server to always encrypt connections.  Likewise you can configure your client machines to always encrypt connections and whether or not to validate the certificate.

Regardless of whether you change either of these settings, all connection/authentication requests to SQL Server (both via SQL Authentication and Windows Authentication) that use the SQL Native Client APIs will always be encrypted no matter what the server or client setting is.  This is because SQL Server creates a self-signed certificate upon installation and uses this to encrypt the connection request.  Once the login credentials are passed and the connection is confirmed, the connection will return to clear text or encrypted (depending on if you required the connection to be encrypted or not).

Remember that there is a small performance hit anytime you decide to require all connections encrypted. 

A note on the "Trust Server Certificate" option in the SQL Native Client properties dialog.  As we discussed before, SQL Server issues a self-signed certificate.  Since this certificate is not signed by a certificate authority it is not automatically trusted (like when you obtain a cert using Verisign, etc).  You could get a signed certificate from one of the certificate authories and upload it to the server if you wish.  This costs some cash though (because the certificate authories charge money for this service).  So how you set this up depends upon how your organization is using SQL Server and its exposure to the outside world. 

 Protecting data while at rest in SQL Server 2005:

Here is where SQL Server 2005 has a lot of added value out of the box.  In the primer section of this post I talked about the basic needs of encryption needing the text, the key and the algorithm.  These actions of creating and managing keys have their own DDL in SQL Server as well as a few built-in functions like EncryptByKey() that make the work of encrypting data -- easy.  You will though have to change some code in your application to make encryption work, there is no magic checkbox (yet) that says, "make this column encrypted" and everyone is happy.  That is currently a mild pain point for some customers in the whole encryption discussion -- just take a few pain killers and continue reading.

The easiest way to demonstrate encryption is to run through a demo.  In this example we have a user called, "HR_User" who needs access to the salary table.

CREATE LOGIN HR_Login WITH PASSWORD='SomeComplexPassword'

GO

CREATE DATABASE ExampleDB

GO

use ExampleDB

GO

CREATE USER HR_User FOR LOGIN HR_Login

GO

--Now we must create a Database Master Key for the ExampleDB.  Database Master Keys

--are used so that SQL Server can encrypt the keys you created.  To protect this key we

--supply a password

CREATE MASTER KEY ENCRYPTION BY PASSWORD='AComplexPassword'

GO

--Create the table that will store sensitive information

--Notice we use a varbinary for our salary information

--This is because the ciphertext (encrypted data) is binary

CREATE TABLE SalaryInfo

(employee nvarchar(50),

department nvarchar(50),

salary varbinary(60))

GO

--Give access to this table to HR_User so they can add data

GRANT SELECT,INSERT TO HR_User

GO

--Create a Symmetric Key

--Encrypt the key with a password

--Give access to the key to HR_User

CREATE SYMMETRIC KEY HR_User_Key

AUTHORIZATION HR_User

WITH ALGORITHM=TRIPLE_DES

ENCRYPTION BY PASSWORD='CompensationPlansRule'

GO

--Now, let's login as HR_User and encrypt some data

EXECUTE AS LOGIN='HR_Login'

GO

--First, we need to open the key that will be used to encrypt data

--Notice we always have to pass the password for the key -- what a pain in the..

OPEN SYMMETRIC KEY HR_User_Key DECRYPTION BY PASSWORD='CompensationPlansRule'

GO

--This system view shows a list of open keys that can be used for encryption

select * from sys.openkeys

--Now let us insert sensitive data into the table

--encryptByKey takes the GUID of the key and the text of the data

--Since remembering GUIDs is not easy, Key_GUID is a function

--that does the lookup for us

INSERT INTO SalaryInfo VALUES

('Bryan','Sales',encryptByKey(Key_GUID('HR_User_Key'),'125000'))

INSERT INTO SalaryInfo VALUES

('Tammie','Sales',encryptByKey(Key_GUID('HR_User_Key'),'122000'))

INSERT INTO SalaryInfo VALUES

('Frank','Development',encryptByKey(Key_GUID('HR_User_Key'),'97500'))

INSERT INTO SalaryInfo VALUES

('Fran','Marketing',encryptByKey(Key_GUID('HR_User_Key'),'99500'))

--When we are done, always close all keys

CLOSE ALL SYMMETRIC KEYS

GO

--View the table as it lives in the database, notice the salary column is all binary

select * from SalaryInfo

--Now, let's decrypt and view the contents

--We use decryptByKey and pass the column name

--We don't have to specify a key GUID because SQL will look

--at all your open keys and use the appropriate one automatically

OPEN SYMMETRIC KEY HR_User_Key DECRYPTION BY PASSWORD='CompensationPlansRule'

GO

SELECT employee,department,

CONVERT(varchar,decryptByKey(salary))

FROM SalaryInfo

GO

CLOSE ALL SYMMETRIC KEYS

GO

--Revert back to sysadmin

REVERT

GO

--When encrypting by password, need to know the password

--and pass it everytime you encrypt something.

--Alternatively you can create a certificate and give access to

--the HR User. With this, the user doesn't have to provide a password

--and you can easily revoke access to that encrypted data by simply

--removing the cert

CREATE CERTIFICATE HRCert1

AUTHORIZATION HR_User

WITH SUBJECT='Certificate used by the Human Resources person'

--Open the key so we can modify it

OPEN SYMMETRIC KEY HR_User_Key DECRYPTION BY PASSWORD='CompensationPlansRule'

GO

--We can not remove the password because we would leave the key

--exposed without encryption so we need to add the certificate first

ALTER SYMMETRIC KEY HR_User_Key

ADD ENCRYPTION BY CERTIFICATE HRCert1

GO

--Now we can remove the password encryption from the key

ALTER SYMMETRIC KEY HR_User_Key

DROP ENCRYPTION BY PASSWORD= 'CompensationPlansRule'

GO

CLOSE ALL SYMMETRIC KEYS

GO

--Now change context to HR_Login to test our changes

EXECUTE AS LOGIN='HR_Login'

GO

--Notice, we opened the key without a password!

--This is because we created the certificate and gave authorization

--on it explicitly to HR_User

OPEN SYMMETRIC KEY HR_User_Key DECRYPTION BY CERTIFICATE HRCert1

GO

SELECT employee,department,

CONVERT(varchar,decryptByKey(salary))

FROM SalaryInfo

GO

This post is meant to give an overview of encryption in SQL Server 2005.  There are two members of the SQL Engine team, Laurentiu Cristofor and Raul Garcia who have blogs dedicated to supporting encryption in SQL Server.  

For information on encryption check out these blogs:

http://blogs.msdn.com/lcris

http://blogs.msdn.com/raulga

 

 

Leave a Comment
  • Please add 3 and 5 and type the answer here:
  • Post
Page 1 of 1 (3 items)