Using LocalDB with Full IIS, Part 2: Instance Ownership

This is the second post in a two-post mini-series on using LocalDB with Full IIS. Don't miss the first post.

Quick Recap

In the first post of this mini-series we said there are two properties of LocalDB causing problems when running under full IIS:

  • LocalDB needs user profile to be loaded
  • LocalDB instance is owned by a single user and private (by default)

We saw how to properly load the user profile, now it's time to tackle the problem of LocalDB instance ownership.

The Problem of the Private Instance

At the end of the previous post we left our Web Application in this state:

As we can see we are facing the following error:

System.Data.SqlClient.SqlException: Cannot open database "OldFashionedDB" requested by the login. The login failed.
Login failed for user 'IIS APPPOOL\ASP.NET v4.0'.

This time the error is quite clear. LocalDB was started and the Web Application was able to connect to it, but the connection was then terminated due to login failure. The ApplicationPoolIdentity account for the IIS application pool (in this case IIS APPPOOL\ASP.NET v4.0) couldn't login to LocalDB instance because the database specified in the connection string (OldFashionedDB) wasn't found. How odd, since connecting from Visual Studio with the same connection string succeeds!

(In this screenshot I am using SQL Server Object Explorer, which is introduced by SQL Server Data Tools. As you can see it adds SQL Server tools right inside Visual Studio 2010.)

How is it possible that Visual Studio connects to LocalDB just fine, while the connection from Web Application fails? In both cases the connection string is the following:

Data Source=(localdb)\v11.0;Initial Catalog=OldFashionedDB;Integrated Security=True

The answer is that there are two different LocalDB instances here. Unlike SQL Server Express instances, which are running as Windows services, LocalDB instances are running as user processes. When different Windows users are connecting to LocalDB, they will end up with different LocalDB processes started for each of them. When we connect to (localdb)\v11.0 from Visual Studio, a LocalDB instance is started for us and runs as our Windows account. But when Web Application, running in IIS as ApplicationPoolIdentity, is connecting to LocalDB, another LocalDB instance is started for it and is running as ApplicationPoolIdentity! In effect, even though both Visual Studio and Web Application are using the same LocalDB connection string, they are connecting to different LocalDB instances. Obviously the database created from Visual Studio on our LocalDB instance will not be available in Web Application's LocalDB instance.

A good analogy to this is My Documents folder in Windows. Say we open Visual Studio and create a file in our My Documents folder. Then we login to the same machine as a different user and go to My Documents folder again. We won't find the file there as My Documents of the second user and our My Documents are two different folders. Similarly LocalDB instances (localdb)\v11.0 owned by two different users are two different processes with two different sets of databases.

This is also the reason the Web Application was able to connect to LocalDB from IIS Express. Just like LocalDB, IIS Express is a user process. It is started by Visual Studio and runs as the same Windows account as the Visual Studio process. Two different processes running as the same Windows account (Visual Studio and IIS Express, both running as our Windows account) connecting to (localdb)\v11.0 are connecting to the same LocalDB process, also started as the same Windows account.

Possible Solutions

Understanding the nature of the problem brings multiple approaches to solving it. As different approaches have different tradeoffs, instead of prescribing one solution, below I presented three approaches that seem most viable to me. My hope is to hear from you about the one that worked best for you! Here is the list:

Let's take a closer look at each of them.

Approach 1: Run IIS as our Windows user

If different user accounts are the problem, why not try to run our Web Application under our Windows account? Web Application would connect to the same LocalDB as Visual Studio and everything should just work.

Making the configuration change is relatively easy, just start IIS Manager and find the right Application Pool:

Open Advanced Settings screen (available in the context menu):

Click the little button in the Identity property to bring up the Application Pool Identity screen:

Starting the Web Application again will confirm that the problem is solved:

What are the drawbacks of this approach? Of course running Web Application under our account brings certain security risks. If someone hijacks our Web Application they will be able to access all system resources our account can. Running the Web Application as ApplicationPoolIdentity provides additional protection since ApplicationPoolIdentity accounts have very limited access to local system resources. Therefore I cannot recommend this approach in general, but when used with care it is a viable option in some cases.

Approach 2: Use LocalDB Shared Instance

We could also use an instance sharing feature of LocalDB. It allows us to share a LocalDB instance with other users on the same machine. The shared instance will be accessible under a public name.

The easiest way of sharing an instance is to use SqlLocalDB.exe utility. Just start an administrative command line prompt, and type the following command:

sqllocaldb share v11.0 IIS_DB

It will share the private LocalDB instance v11.0 under the public name IIS_DB. All users on the machine will be able to connect to this instance, using (localdb)\.\IIS_DB as a server address. Note the \. before the instance name, indicating this is a shared instance name. We should replace the connection string in our Web Application with an updated one:

Data Source=(localdb)\.\IIS_DB;Initial Catalog=OldFashionedDB;Integrated Security=True

Before the shared instance can be used by the Web Application we need to start it and create logins for the ApplicationPoolIdentity. Starting the instance is easy, simply connecting to it from SQL Server Object Explorer will start it and keep it alive. Once we are in the SQL Server Object Explorer we can also create the login for ApplicationPoolIdentity. We could use the following query:

create login [IIS APPPOOL\ASP.NET v4.0] from windows;
exec sp_addsrvrolemember N'IIS APPPOOL\ASP.NET v4.0', sysadmin

This script gives full administrative access to our LocalDB instance to the ApplicationPoolIdentity account. Whenever possible, I would recommend using more limited, database-level or even table-level permissions.

Now we can run our Web Application again. This time it should work just fine:

What are the drawbacks of this approach? The main one is that, before Web Application can connect to the shared instance, we need to make sure the instance is started. For that to happen the Windows account that owns the instance must connect to it and the connection must be kept open, or the LocalDB instance will shut down.

Approach 3: Use full SQL Server Express

Since full IIS runs as a service, maybe using traditional, service-based SQL Server Express is the right approach? We could just install SQL Server 2012 Express RC0 and create the OldFashionedDB database in it. We can even use our brand new SQL Server Data Tools to do it, as it works with any SQL Server version and edition. Our connection string would have to change to:

Data Source=.\SQLEXPRESS;Initial Catalog=OldFashionedDB;Integrated Security=True

Of course, just as in the previous case, we would need to make sure the ApplicationPoolIdentity account has access to our SQL Server Express instance. We can use the same script as previously:

create login [IIS APPPOOL\ASP.NET v4.0] from windows;
exec sp_addsrvrolemember N'IIS APPPOOL\ASP.NET v4.0', sysadmin

After that, running our Web Application brings the happy picture again:

What are the drawbacks of this approach? Obviously we lose the benefits of using LocalDB. Installing SQL Server Express may take more time than LocalDB, and there may be some machine cleanup necessary for it to succeed. SQL Server Express Setup can be blocked by problems like corrupt WMI database, polluted registry or components left by SQL Server or Visual Studio CTPs and Betas. And SQL Server Express will continue running in the background even when not needed, as services do.

Other options

There are other approaches of using LocalDB under full IIS that are not covered here. We could embrace the Web Application's private LocalDB instance and communicate with it through the Web Application by executing T-SQL scripts from ASP.NET code. We could also use AttachDbFileName option of ADO.NET connection strings and use a database file (.mdf) that would be attached to both our LocalDB during development and Web Application's LocalDB for debugging. I tried both I found them too cumbersome to discuss further.

Try It Now!

We are eager to hear your feedback on LocalDB. Please share your thoughts with us. Did any of the approaches presented in this post work for you? Did you figure out a better one? Let us know!

You may also want to see other posts and materials about LocalDB:

- Krzysztof Kozielczyk

Share Your Feedback

Please share your feedback with us! Just start a thread on SQL Express Forum, hit the "Email Author" button on this post, or file a Connect item!