Thursday, July 19, 2012

Migrating to a Contained Database in SQL Server 2012


A few days ago, an article of mine on Contained Databases in SQL Server 2012 was published on the MVP Award Program Blog.

In that article I explained with an example how you can easily create and access a partially contained database from scratch.

This is the second part of the article that explains how you can convert a "normal" database to a partially contained database thus making it fully portable.

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).

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



















































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

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):



































Enter the contained database's user credentials:























Access granted!







































I hope you enjoyed the post!

Cheers!

[Ads]
Check out my latest eBook on SQL Server:
Tuning SQL Server - Ebook

Easily secure your SQL Server instances! Try out DBA Security Advisor!
DBA Security Advisor for SQL Server by SQLArtBits
DBA Security Advisor was developed by SQLArtBits. The tool was being carefully developed for an entire year and it contains comprehensive security checks and recommendations based on proven SQL Server security best practices. Feel free to download and use the Community Edition which is free and if you find it useful, you can consider upgrading to the Enterprise Edition!

Artemakis Artemiou [MVP]

Author & Editor

Artemakis Artemiou is a Senior SQL Server Architect, Software Developer and Microsoft Data Platform MVP. He is also an author, regular blogger, president of Cyprus.NET User Group and CY Country leader of INETA-EU. He is also the creator of DBA Security Advisor and In-Memory OLTP Simulator. Artemakis is a frequent guest author of worldwide well-respected online journals where he writes articles focusing on many SQL Server topics.

Reference: The SQL Server and .NET Hub (http://www.sqlnethub.com)

0 comments: