Migrating to a Contained Database in SQL Server

In this article, we will discuss about migrating to a contained database in SQL Server

To this end, we will see how we can convert a “normal” database to a partially contained database in SQL Server.

A typical security/user access configuration for a database would be set up as follows: Create the login (SQL or Windows) under the SQL Server Instance “Security” module, and then set the proper “User Mapping” along with the corresponding database role membership(s).

 

Example of Migrating to a Contained Database in SQL Server

This is illustrated in the following screenshot where we see the user access configuration for the sample database “NormalDB”:

Migrating to a Contained Database in SQL Server - SQLNetHub

However, what would you do if you needed to migrate the database to another instance? If you did not migrate the SQL login as well, you would encounter the issue of orphaned database users (not associated to a SQL login).

With partially contained databases there is not such an issue for the simple reason that you do not need to have a SQL login associated to the database user, you just need the database user! 🙂

So, let’s see how we can convert “NormalDB” to a partially contained database.

First of all, we need to enable “contained database authentication” on the SQL Server instance if not already enabled:

USE [master]
GO

sp_configure 'contained database authentication', 1
GO
RECONFIGURE
GO

 


Strengthen your SQL Server Administration Skills – Enroll to our Online Course!

Check our online course on Udemy titled “Essential SQL Server Administration Tips
(special limited-time discount included in link).

Via the course, you will learn essential hands-on SQL Server Administration tips on SQL Server maintenance, security, performance, integration, error handling and more. Many live demonstrations and downloadable resources included!

Essential SQL Server Administration Tips - Online Course with Live Demonstrations and Hands-on Guides
(Lifetime Access/ Live Demos / Downloadable Resources and more!)

Learn More


Then, we change the containment option for the database to “PARTIAL“:

ALTER DATABASE [NormalDB]
SET CONTAINMENT=PARTIAL
GO

 

And here’s the last step where the magic takes place:

USE [NormalDB]
GO

sp_migrate_user_to_contained 
@username = N'NormalDBLogin',
@rename = N'keep_name',
@disablelogin = N'disable_login'
GO

 

sp_migrate_user_to_contained is a special stored procedure shipped with SQL Server 2012 and its purpose is to remove dependencies between a database and the SQL Server instance that hosts it. More specifically, it separates the user from the original SQL Server login.

In the above example, what sp_migrate_user_to_contained did was to set the login’s password to the contained database user and then remove the SQL Server login.

So, it’s time to access that contained database!

Set the database to connect to (NormalDB):

Migrating to a Contained Database in SQL Server - SQLNetHub

 

Enter the contained database’s user credentials:

Migrating to a Contained Database in SQL Server - SQLNetHub

Access granted!

Migrating to a Contained Database in SQL Server - SQLNetHub

Featured Online Courses:

 

Read Also

 

Featured Database Security and Administration Tool: DBA Security Advisor

DBA Security Advisor: Secure your SQL Server instances by scanning multiple instances against a rich set of security checks, and by getting recommendations and remediation steps.

DBA Security Advisor - SQL Server Security and Administration Tool

Learn more

 

Did you find this article useful and interesting? Feel free to leave your comment!

If you enjoy my SQL Server administration tips and articles, I have something special just for you. It is one of my eBooks and it is called “Administering SQL Server“. Check it out!

Subscribe to our newsletter and stay up to date with our latest articles on SQL Server and related technologies!

Check out our latest software releases! All our software tools have 30-day Trial Versions which are free to download.

 

Rate this article: 1 Star2 Stars3 Stars4 Stars5 Stars (2 votes, average: 5.00 out of 5)

Loading...

Reference: SQLNetHub.com (https://www.sqlnethub.com)

© SQLNetHub