Let us create a database:
create database encrypt_testChange to this new database:
use encrypt_test
Now add a database master key:
create master key encryption by password = 'pwd123'
Some subtle points here:
1. Database master key cannot be just created with service master key, it needs a password for creation.
2. 'create master key' automatically encrypts master key by service master key. Therefore, if you wish the master key to be opened by password only, you must drop encryption by service master key at this stage. However, you must consider the situation of losing the master key password before dropping encryption by service master key since it can be your only saviour when you lose the master key password.
Now let us create a table:
create table crypto(
actual int,
encrypted varbinary(256)
)
Let us add some data to play with:
insert into crypto(actual)
select number from master..spt_values where type = 'p'
go 100
Add a certificate and symmetric key:
create certificate crypto_cert with subject = 'crypto'
create symmetric key crypto_key with algorithm = triple_des encryption by certificate crypto_cert
Open the symmetric key to encrypt data:
open symmetric key crypto_key decryption by certificate crypto_cert
Check if it is open alright:
select * from sys.openkeys
Go for a test drive of encryption:
select top 20 actual, encryptbykey(key_guid('crypto_key'),convert(varchar(10),actual)) from crypto
Enough, now encrypt the data:
update crypto
set encrypted = encryptbykey(key_guid('crypto_key'),convert(varchar(10),actual))
How about checking the encrypted value:
select top 20 actual, convert(varchar(10),decryptbykey(encrypted)) from crypto
All is well till you lose the master key password . If you have dropped encryption by service master key, you cannot retrieve the encrypted data. Therefore, it is a good practice to add encryption by service master key to safeguard against such situation.
Regenerate the master key:
alter master key regenerate with encryption by password = '123pwd'
Regenerate uses the service master key to open the master key followed by decrypting and encrypting the certificate/symmetric keys (it does not re-encrypt the data). If the old master key cannot be opened, regenerate will fail.
After regerate succeeds, open the master key and add encryption by service master key:
open master key decryption by password = '123pwd'
alter master key add encryption by service master key
Note that database master key regeneration is different from service master key regeneration.