21 March, 2021

The Resource Database in SQL Server

 The "master" and "msdb" databases in a SQL Server installation are visible through SSMS.

However, every installation also includes a "Resource" database.  This is a static database which is not directly accessed or accessible.  It is installed into the SQL Server Version BINN folder and consists of both an "mdf" and "ldf" file.  This is where the actual definitions of system objects are stored.  This is the source database for definitions that "master" can read.  And this is the actual database that is upgraded when you do a SQL Server upgrade and may also be bundled in a patch release.

So, if you filter my SQL Server Log for entries referring to this before and after the CU23 patch that I applied recently, I see :

Resource Database Reference in SQL Server Log


Notice how the build version "14.00.2037"  got updated  to " 14.00.3381" when I applied CU23.

This Resource Database is how the "master" database update entries that I showed in my previous blog post are executed very quickly, most of them are links or hooks back to the Resource Database.


The Resource Database consists of the two files "mssqlsystemresource.mdf and mssqlsystemresource.ld" the SQL Server installed version "BINN" folder.  If you copy them out and attempt to attach the copy as a database, using SSMS, you get this error :

Error when trying to attach copy of Resource Database

with more details as :

Details on error attempting to attach copy of Resource Database


This is the Microsoft Documentation on the Resource Database 

When I run the queries shown in the Microsoft document, I get :

Resource Database Properties


Do not attempt your own Backup/Restore of this database.  But do ensure that your SQL Server Installation folder is backed up frequently, including after applying Service Packs and Cumulative Updates.  You would need to refer to this backup (or such a backup from another server having the same SQL Server Version and Patch Level) if you ever need to restore this database.



19 March, 2021

Patching SQL Server

 Starting with SQL Server 2017, Microsoft no longer releases Service Packs but only Cumulative Updates.

(I find this similar to Oracle releasing Release Updates, instead of Patch Set Updates, beginning with Oracle 12.2)

Refer to this page for the latest SQL Server Updates

This is the current SQLServer 2017 version I have on my desktop :

Current SQL Server Version query in SSMS

I have downloaded CU 23  (SQLServer2017-KB5000685-x64.exe) and proceed to apply this patch.

Installer Screen for SQL Server Cumulative Update


I have two separate installations of SQL Server on my desktop and choose to update only the second installation.

Select SQL Server Installation to update


I then confirm the location to install the Update


Confirm the Installation to be Updated


The installation proceeds and completes successfully

Installation of Update is in progress


Installation of Update is completed


When I query for the version, I see the updated version  -- CU23 has been applied

Version has been updated to CU23


Some DBAs have asked me.  Why is it that Oracle, after running "opatch",  has to run a separate datapatch to run SQL "Apply" actions when SQL Server does not need to do any SQL actions ?

The truth is that SQL Server Patching *does do* a lot of SQL "Apply" actions.  It is just that Microsoft does not ask you to run a separate datapatch command like Oracle.  An Oracle Home can have multiple databases so the patch for binaries is applied only once but the datapatch command has to be run for each database.  In the case of SQL Server all the databases in an Instance share common "master" and "msdb" database that are upgraded when you run the Patch Installer exe.  After applying those changes, it restarts the instance.

So if you want to identify the SQL Apply actions, look at the Archive (#1 or even #2) depending on the number of restarts.

In my case Archive#1 has 2,530 lines of entries over 36seconds.

I just show some of those entries here to prove that applying a SQL Server Patch also may involve a number of SQL Actions :

Here are some entries (from the bottom up) from Archive #1 of the SQL Server Log :








(There are 255 "Dropping signature" commands here)


(There are about 170 "Creating ..." commands here)


(about 30 "deprecated permissions")



(about70 "Creating ..." commands here)



                                                (and more Drops and Creates)


Some interesting entries here below :


















And the final set of messages before the instance is shutdown :


The next startup then is when the Patching utility releases the Instance for usage.

So, Microsoft SQL Server Patching does do a large number of changes to "master" and "msdb" and configurations.  Do you go in and identify critical changes that need to be tested ?










12 March, 2021

Setting up Transparent Data Encryption

 In a SQL Server instance you can choose to selectively configure TDE (Transparent Data Encryption) on target databases.  So, it doesn't become necessary to have all the databases configured with TDE.

(Similarly, in Oracle you can selectively configure target tablespace(s).)


This is a quick walkthrough.

Step 1 : Create a Master Key, using a password that should be protected

Create Master Key in MASTER Database


Step 2 :  Create a Certificate (it is automatically protected by the Master Key)

Create Certificate


Step 3 : Create a Database Encryption Key for the Target Database

Create Database Encryption Key

Note : You are immediate presented with a warning that the Certificate has not been backed up.
We shall backup the certificate soon.


Step 4: Turn on Database Encryption

Turn On Database Encryption


Step 5 : List the Certificates that have been created

List the Certficates that have been created

The first 7 Certificates are pre-populated by the Instance.  The Certificate that I have created "My_TDE_Certificate" is listed as certificate_id=258 and encrypted by the Master Key




Step 6 : List the Encrypted Databases

List Encrypted Databases

This is the explanation of the EncryptionState :
0 = No database encryption key present, no encryption

1 = Unencrypted

2 = Encryption in progress

3 = Encrypted

4 = Key change in progress

5 = Decryption in progress

6 = Protection change in progress (The certificate or asymmetric key that is encrypting the database encryption key is being changed.)


You would see EncryptionState=3 only after some time for a large database as the "SET ENCRYPTION ON" takes time to run through the whole database.




Step 7 : Backup the Certificate


Backup the Certificate

Certificate and Private Key Backups



These two backup files (and the Password) must be protected -- e.g. by running backup to another safe device.




If you ever need to restore the database "MY_HR_DB" to another Server, you will need to configure the Master Key and create the Certificate on that server before you can restore the database :
USE MASTER
GO
CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'My_123_Secret'
GO


CREATE CERTIFICATE My_TDE_Certificate
FROM FILE = 'D:\SS_Important_Backups\My_TDE_Certificate.cert'
WITH PRIVATE KEY (FILE = 'D:\SS_Important_Backups\My_TDE.key',
DECRYPTION BY PASSWORD 'My_123_Secret');


The database cannot be restored and read on another server unless the Master Key and Certificate are configured on the new server.


To disable (remove) Encryption you can  run :
ALTER DATABASE MY_HR_DB SET ENCRYPTION OFF;
GO
/* Wait for decryption operation to complete, look for a value of 1 in the query below. */

SELECT encryption_state FROM sys.dm_database_encryption_keys;
GO

USE MY_HR_DB;
GO

DROP DATABASE ENCRYPTION KEY;
GO


Again, as with setting up Encryption, disabling it can take time to execute.  Note that older backups of the Database and Transaction Logs would still remain in an Encrypted State.



This is the listing of all the commands in this post :
USE MASTER
CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'My_123_Secret';

CREATE CERTIFICATE My_TDE_Certificate WITH SUBJECT= ' TDE_Configuration' ;

USE MY_HR_DB
GO

CREATE DATABASE ENCRYPTION KEY
WITH ALGORITHM = AES_256
ENCRYPTION BY SERVER CERTIFICATE My_TDE_Certificate;
GO


USE MASTER
GO

SELECT name, certificate_id, principal_id, pvt_key_encryption_type_desc, start_date, expiry_date
FROM sys.certificates;



SELECT
DB_NAME(database_id) AS DatabaseName
,Encryption_State AS EncryptionState
,key_algorithm AS Algorithm
,key_length AS KeyLength
FROM sys.dm_database_encryption_keys
GO


BACKUP CERTIFICATE My_TDE_Certificate 
TO FILE = 'D:\SS_Important_Backups\My_TDE_Certificate.cert'
WITH PRIVATE KEY (file='D:\SS_Important_Backups\My_TDE.key',
ENCRYPTION BY PASSWORD = 'My_123_Secret')



USE MASTER
GO
CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'My_123_Secret'
GO


CREATE CERTIFICATE My_TDE_Certificate
FROM FILE = 'D:\SS_Important_Backups\My_TDE_Certificate.cert'
WITH PRIVATE KEY (FILE = 'D:\SS_Important_Backups\My_TDE.key',
DECRYPTION BY PASSWORD 'My_123_Secret');




ALTER DATABASE MY_HR_DB SET ENCRYPTION OFF;
GO
/* Wait for decryption operation to complete, look for a value of 1 in the query below. */

SELECT encryption_state FROM sys.dm_database_encryption_keys;
GO

USE MY_HR_DB;
GO

DROP DATABASE ENCRYPTION KEY;
GO


As noted earlier, an Instance can have a mix of Encrypted (TDE) and Non-Encrypted Databases. TDE does "encryption at rest" -- meaning that the  files on the OS layer (Database, Transaction Log and Backups of both) are encrypted.