Skip to content

Commit

Permalink
First commit
Browse files Browse the repository at this point in the history
  • Loading branch information
Apress committed Oct 13, 2016
0 parents commit 2bf24f0
Show file tree
Hide file tree
Showing 190 changed files with 4,321 additions and 0 deletions.
27 changes: 27 additions & 0 deletions LICENSE.txt
@@ -0,0 +1,27 @@
Freeware License, some rights reserved

Copyright (c) 2009 Michael Coles and Rodney Landrum

Permission is hereby granted, free of charge, to anyone obtaining a copy
of this software and associated documentation files (the "Software"),
to work with the Software within the limits of freeware distribution and fair use.
This includes the rights to use, copy, and modify the Software for personal use.
Users are also allowed and encouraged to submit corrections and modifications
to the Software for the benefit of other users.

It is not allowed to reuse, modify, or redistribute the Software for
commercial use in any way, or for a user�s educational materials such as books
or blog articles without prior permission from the copyright holder.

The above copyright notice and this permission notice need to be included
in all copies or substantial portions of the software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS OR APRESS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.


15 changes: 15 additions & 0 deletions README.md
@@ -0,0 +1,15 @@
#Apress Source Code

This repository accompanies [*Expert SQL Server 2008 Encryption*](http://www.apress.com/9781430224648) by Michael Coles and Rodney Landrum (Apress, 2009).

![Cover image](9781430224648.jpg)

Download the files as a zip using the green button, or clone the repository to your machine using Git.

##Releases

Release v1.0 corresponds to the code in the published book, without corrections or updates.

##Contributions

See the file Contributing.md for more information on how you can contribute to this repository.
5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-01.sql
@@ -0,0 +1,5 @@
-- Listing 2-1
-- Encryption key backup

BACKUP SERVICE MASTER KEY TO FILE = N'C:\MyServiceMasterKey.key'
ENCRYPTION BY PASSWORD = N'$45^ZeF&u';
5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-02.sql
@@ -0,0 +1,5 @@
-- Listing 2-2
-- Encryption key restore

RESTORE SERVICE MASTER KEY FROM FILE = N'C:\MyServiceMasterKey.key'
DECRYPTION BY PASSWORD = N'$45^ZeF&u';
7 changes: 7 additions & 0 deletions Source-Code/Chapter02/Listing02-03.sql
@@ -0,0 +1,7 @@
-- Listing 2-3
-- Change SMK account

ALTER SERVICE MASTER KEY
WITH NEW_ACCOUNT = N'SQL2008Server\Michael', -- Replace account name with your service account name
NEW_PASSWORD = N'^&3h4l1xPr';

5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-04.sql
@@ -0,0 +1,5 @@
-- Listing 2-4
-- Regenerate SMK

ALTER SERVICE MASTER KEY REGENERATE;

5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-05.sql
@@ -0,0 +1,5 @@
-- Listing 2-5
-- Create DMK

CREATE MASTER KEY ENCRYPTION BY PASSWORD = N'a0*Ui)4x-f';

6 changes: 6 additions & 0 deletions Source-Code/Chapter02/Listing02-06.sql
@@ -0,0 +1,6 @@
-- Listing 2-6
-- Drop DMK encryption by SMK

ALTER MASTER KEY
DROP ENCRYPTION BY SERVICE MASTER KEY;

12 changes: 12 additions & 0 deletions Source-Code/Chapter02/Listing02-07.sql
@@ -0,0 +1,12 @@
-- Listing 2-7
-- Add and remove DMK encryption by password

-- Add encryption by password
ALTER MASTER KEY ADD ENCRYPTION BY PASSWORD = N'9(%^jQ!@#d';
GO

-- Remove encryption by password
ALTER MASTER KEY DROP ENCRYPTION BY PASSWORD = N'9(%^jQ!@#d';
GO


6 changes: 6 additions & 0 deletions Source-Code/Chapter02/Listing02-08.sql
@@ -0,0 +1,6 @@
-- Listing 2-8
-- Regenerate a DMK

ALTER MASTER KEY REGENERATE WITH ENCRYPTION BY PASSWORD = N'$4yAxU%t7';


5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-09.sql
@@ -0,0 +1,5 @@
-- Listing 2-9
-- Backup a DMK

BACKUP MASTER KEY TO FILE = N'C:\MyDatabaseMasterKey.key'
ENCRYPTION BY PASSWORD = N'0-!t4=Rtr=,';
7 changes: 7 additions & 0 deletions Source-Code/Chapter02/Listing02-10.sql
@@ -0,0 +1,7 @@
-- Listing 2-10
-- Restoring a DMK

RESTORE MASTER KEY FROM FILE = N'C:\MyDatabaseMasterKey.key'
DECRYPTION BY PASSWORD = N'0-!t4=Rtr=,'
ENCRYPTION BY PASSWORD = N'p#v8A0@+|';

5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-11.sql
@@ -0,0 +1,5 @@
-- Listing 2-11
-- Dropping a DMK

DROP MASTER KEY;

6 changes: 6 additions & 0 deletions Source-Code/Chapter02/Listing02-12.sql
@@ -0,0 +1,6 @@
-- Listing 2-12
-- Opening a DMK

OPEN MASTER KEY
DECRYPTION BY PASSWORD = N'$4yAxU%t7';

5 changes: 5 additions & 0 deletions Source-Code/Chapter02/Listing02-13.sql
@@ -0,0 +1,5 @@
-- Listing 2-13
-- Closing a DMK

CLOSE MASTER KEY;

14 changes: 14 additions & 0 deletions Source-Code/Chapter02/Listing02-14.sql
@@ -0,0 +1,14 @@
-- Listing 2-14
-- Retrieve list of asymmetric keys from current database

SELECT
name,
asymmetric_key_id,
pvt_key_encryption_type_desc,
thumbprint,
algorithm_desc,
key_length,
public_key
FROM sys.asymmetric_keys;


15 changes: 15 additions & 0 deletions Source-Code/Chapter02/Listing02-15.sql
@@ -0,0 +1,15 @@
-- Listing 2-15
-- Retrieve list of certificates from current database

SELECT
name,
certificate_id,
pvt_key_encryption_type_desc,
subject,
cert_serial_number,
start_date,
expiry_date,
thumbprint
FROM sys.certificates;


14 changes: 14 additions & 0 deletions Source-Code/Chapter02/Listing02-16.sql
@@ -0,0 +1,14 @@
-- Listing 2-16
-- Retrieve list of EKM provider credentials

SELECT
credential_id,
name,
credential_identity,
create_date,
modify_date,
target_type,
target_id
FROM sys.credentials;


14 changes: 14 additions & 0 deletions Source-Code/Chapter02/Listing02-17.sql
@@ -0,0 +1,14 @@
-- Listing 2-17
-- Retrieve list of registered cryptographic providers

SELECT
provider_id,
name,
guid,
version,
dll_path,
is_enabled
FROM sys.cryptographic_providers;



13 changes: 13 additions & 0 deletions Source-Code/Chapter02/Listing02-18.sql
@@ -0,0 +1,13 @@
-- Listing 2-18
-- Retrieve cryptographic properties

SELECT
o.name AS object_name,
SCHEMA_NAME(o.schema_id) AS object_schema,
cp.major_id,
cp.class_desc,
cp.crypt_type_desc,
cp.thumbprint
FROM sys.crypt_properties cp
INNER JOIN sys.all_objects o
ON cp.major_id = o.object_id;
16 changes: 16 additions & 0 deletions Source-Code/Chapter02/Listing02-19.sql
@@ -0,0 +1,16 @@
-- Listing 2-19
-- Retrieve symmetric keys that are encrypted by certificate

SELECT
sk.name AS key_name,
ke.crypt_type_desc,
ke.crypt_property,
c.name AS cert_name,
sk.algorithm_desc AS key_algorithm_desc,
sk.key_length,
ke.thumbprint
FROM sys.key_encryptions ke
INNER JOIN sys.symmetric_keys sk
ON sk.symmetric_key_id = ke.key_id
INNER JOIN sys.certificates c
ON ke.thumbprint = c.thumbprint;
10 changes: 10 additions & 0 deletions Source-Code/Chapter02/Listing02-20.sql
@@ -0,0 +1,10 @@
-- Listing 2-20
-- Retrieve algorithms supported by cryptographic provider

SELECT
algorithm_id,
algorithm_tag,
key_type,
key_length
FROM sys.dm_cryptographic_provider_algorithms (65536); -- replace 65536 with your own cryptographic provider ID

12 changes: 12 additions & 0 deletions Source-Code/Chapter02/Listing02-21.sql
@@ -0,0 +1,12 @@
-- Listing 2-21
-- Retrieve keys exposed by cryptographic provider

SELECT
key_id,
key_name,
algorithm_tag,
key_type,
key_length,
key_thumbprint
FROM sys.dm_cryptographic_provider_keys (65536); -- replace 65536 with your own cryptographic provider ID

13 changes: 13 additions & 0 deletions Source-Code/Chapter02/Listing02-22.sql
@@ -0,0 +1,13 @@
-- Listing 2-22
-- Retrieve properties and feature support flags of EKM provider

SELECT
provider_id,
provider_version,
sqlcrypt_version,
friendly_name,
authentication_type,
symmetric_key_support,
asymmetric_key_support
FROM sys.dm_cryptographic_provider_properties;

9 changes: 9 additions & 0 deletions Source-Code/Chapter02/Listing02-23.sql
@@ -0,0 +1,9 @@
-- Listing 2-23
-- Enumerate all open cryptographic provider session

SELECT
provider_id,
session_handle,
[identity],
spid
FROM sys.dm_cryptographic_provider_sessions(1);
13 changes: 13 additions & 0 deletions Source-Code/Chapter02/Listing02-24.sql
@@ -0,0 +1,13 @@
-- Listing 2-24
-- Enumerate database encryption keys

SELECT
d.name AS db_name,
dbek.encryption_state,
dbek.key_algorithm,
dbek.key_length,
dbek.percent_complete
FROM sys.dm_database_encryption_keys dbek
INNER JOIN sys.databases d
ON dbek.database_id = d.database_id;

15 changes: 15 additions & 0 deletions Source-Code/Chapter03/Listing03-01.sql
@@ -0,0 +1,15 @@
-- Listing 3-1
-- Enumerate database encryption keys

CREATE TABLE SalesLT.EncryptedCustomer
(
CustomerID int NOT NULL PRIMARY KEY,
FirstName varbinary(200),
MiddleName varbinary(200),
LastName varbinary(200),
EmailAddress varbinary(200),
Phone varbinary(150),
rowguid uniqueidentifier
);
GO

8 changes: 8 additions & 0 deletions Source-Code/Chapter03/Listing03-02.sql
@@ -0,0 +1,8 @@
-- Listing 3-2
-- Create a certificate

CREATE CERTIFICATE Cert1_Sales
WITH SUBJECT = N'Sales Certificate',
START_DATE = N'2009-01-01',
EXPIRY_DATE = N'2018-12-31';
GO
10 changes: 10 additions & 0 deletions Source-Code/Chapter03/Listing03-03.sql
@@ -0,0 +1,10 @@
-- Listing 3-3
-- Create a AES 256 symmetric key

CREATE SYMMETRIC KEY SymKey1_Sales
WITH ALGORITHM = AES_256,
IDENTITY_VALUE = N'Barbarians at the Gate',
KEY_SOURCE = N'We will leave the light on for you'
ENCRYPTION BY CERTIFICATE Cert1_Sales;
GO

39 changes: 39 additions & 0 deletions Source-Code/Chapter03/Listing03-04.sql
@@ -0,0 +1,39 @@
-- Listing 3-4
-- Encrypt data with a symmetric key

-- First wipe out the target table
TRUNCATE TABLE SalesLT.EncryptedCustomer;
GO

-- Open the key that's protected by certificate
OPEN SYMMETRIC KEY SymKey1_Sales
DECRYPTION BY CERTIFICATE Cert1_Sales;
GO

-- Encrypt the data
INSERT INTO SalesLT.EncryptedCustomer
(
CustomerID,
FirstName,
MiddleName,
LastName,
EmailAddress,
Phone,
rowguid
)
SELECT
CustomerID,
EncryptByKey(Key_Guid(N'SymKey1_Sales'), FirstName),
EncryptByKey(Key_Guid(N'SymKey1_Sales'), MiddleName),
EncryptByKey(Key_Guid(N'SymKey1_Sales'), LastName),
EncryptByKey(Key_Guid(N'SymKey1_Sales'), EmailAddress),
EncryptByKey(Key_Guid(N'SymKey1_Sales'), Phone),
rowguid
FROM SalesLT.Customer;
GO

-- Close the key
CLOSE SYMMETRIC KEY SymKey1_Sales;
GO


9 changes: 9 additions & 0 deletions Source-Code/Chapter03/Listing03-05.sql
@@ -0,0 +1,9 @@
-- Listing 3-5
-- View encrypted binary data

SELECT
CustomerID,
FirstName
FROM SalesLT.EncryptedCustomer;
GO

20 changes: 20 additions & 0 deletions Source-Code/Chapter03/Listing03-06.sql
@@ -0,0 +1,20 @@
-- Listing 3-6
-- View encrypted character data

-- Open the key that's protected by certificate
OPEN SYMMETRIC KEY SymKey1_Sales
DECRYPTION BY CERTIFICATE Cert1_Sales;
GO

-- Decrypt the data
SELECT
CustomerID,
CAST(DecryptByKey(FirstName) AS nvarchar(100)) AS DecryptedFirstName,
FirstName
FROM SalesLT.EncryptedCustomer;
GO

-- Close the key
CLOSE SYMMETRIC KEY SymKey1_Sales;
GO

0 comments on commit 2bf24f0

Please sign in to comment.