MSSQL Configure Database Encryption

Configure database encryption and backup keys en certificates. This manual shows the complete chain from Service Master Key to the Database Encryption Key. Please remember to at least backup the Server Certificate (marked: “[*** IMPORTANT ***]”) and store these files in a secure location. Without this certificate you cannot access your data when it’s moved or restored to another server. You should substitute all (random generated) passwords with your own.

STEP 1 – Backup and restore (for verification purposes) Service Master Key.

USE master;
GO

-- Backup Service Master Key...
BACKUP SERVICE MASTER KEY TO FILE = 'X:\Path\To\ServiceMaster.key' 
ENCRYPTION BY PASSWORD = 'ooxuRai4shaid0AvnieLoh6t'

-- Restore Service Master Key...
RESTORE SERVICE MASTER KEY FROM FILE = 'X:\Path\To\ServiceMaster.key' 
DECRYPTION BY PASSWORD = 'ooxuRai4shaid0AvnieLoh6t' FORCE

STEP 2 – Create, backup and restore (for verification purposes) Database Master Key and Server Certificate.

USE master;
GO

-- Create Database Master Key...
CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'eeLohz8iJuapo5mekohng0Ah';
GO

-- Backup Database Master Key...
BACKUP MASTER KEY TO FILE = 'X:\Path\To\Master.key'
ENCRYPTION BY PASSWORD = 'eeLohz8iJuapo5mekohng0Ah'
GO

-- Drop Database Master Key for restore test...
DROP MASTER KEY
GO

-- Restore Database Master Key...
RESTORE MASTER KEY FROM FILE = 'X:\Path\To\Master.key' 
DECRYPTION BY PASSWORD = 'eeLohz8iJuapo5mekohng0Ah'
ENCRYPTION BY PASSWORD = 'eeLohz8iJuapo5mekohng0Ah'
GO

-- Open key and let Service Master Key decrypt (for transparent encryption)...
OPEN MASTER KEY DECRYPTION BY PASSWORD = 'eeLohz8iJuapo5mekohng0Ah'
GO
ALTER MASTER KEY ADD ENCRYPTION BY SERVICE MASTER KEY
GO

-- Create Server Certificate...
CREATE CERTIFICATE ServerCertDefault WITH SUBJECT = 'Server Certificate Default'
GO

-- Backup Server Certificate and Key [*** IMPORTANT ***]...
BACKUP CERTIFICATE ServerCertDefault TO FILE = 'X:\Path\To\ServerCertDefault.cer'
WITH PRIVATE KEY ( FILE = 'X:\Path\To\ServerCertDefault.key', 
ENCRYPTION BY PASSWORD = 'Eeh3aeb0EiTh2ohZneil8ueS' );
GO

-- Remove Server Certificate for restore test....
DROP CERTIFICATE ServerCertDefault
GO

-- Restore Server Certificate with Key...
CREATE CERTIFICATE ServerCertDefault 
FROM FILE = 'X:\Path\To\ServerCertDefault.cer'
WITH PRIVATE KEY ( FILE = 'X:\Path\To\ServerCertDefault.key' , 
DECRYPTION BY PASSWORD = 'Eeh3aeb0EiTh2ohZneil8ueS' );
GO

STEP 3 – Turn on database encryption in database.

USE [Database]
GO

-- Create Database Encryption Key...
CREATE DATABASE ENCRYPTION KEY WITH ALGORITHM = AES_128
ENCRYPTION BY SERVER CERTIFICATE ServerCertDefault
GO

-- Enable Encryption...
ALTER DATABASE [Database] SET ENCRYPTION ON
GO

-- Check if database encryption is turned on...
SELECT name, is_encrypted FROM sys.databases WHERE is_encrypted = 1

Results:
name                                                           is_encrypted
-------------------------------------------------------------- ------------
DatabaseName                                                   1

PowerShell Auto Add Database to SQL AllwaysOn Availability Group

This script adds all user databases which are not yet replicated to a specific SQL Server AlwaysOn Availability Group. After that a check procedure is started to check if replication state for all databases exists and are healthy. Alerts can be send to an e-mail address or to the Windows Eventlog (or both).

This script uses custum functions fnSendMailfnWriteEventLog to send alert messages and fnSQLCmd for handeling SQL statements.

AdminFunctions PowerShell Module (SendMail, WriteEventLog, SQLCmd and more)…


Download AutoAddDatabases2AvailabilityGroup code
Download AdminFunctions code

GNU/Linux ODATA Query Examples

ODATA Query Option Description
$orderby Uri parameter for sorting…
$select Uri parameter to select specific coluimns…
$top Uri parameter to limit the result…
$skip Uri parameter to skip number of rows…
$filter Uri parameter to filter result…
$expand Uri parameter to expand related entity…
$inlinecount Uri parameter to include a total record count…

 

Example to retrieve metadata from JBoss DV Odata service…

https://localhost:8443/odata/vdbname/$metadata

 

Retrieve all records in JSON format…

https://localhost:8443/odata/vdbname/modelname?$format=json

 

Order by column ‘Name’ and retrieve first 5 records…

https://localhost:8443/odata/vdbname/modelname?amp;$orderby=Name&$top=5

 

Order by column ‘Name’ and retrieve records 6-10 records…

https://localhost:8443/odata/vdbname/modelname?$orderby=Name&skip=5&$top=5

 

Filter ODATA result ($filter=Name eq ‘John’)…

https://localhost:8443/odata/vdbname/modelname?$filter=Name%20eq%20%27John%27

Select specific rows…

https://localhost:8443/odata/vdbname/modelname?$select=ID,Name,Description