SALES: 1-800-867-1380
125 out of 240 rated this helpful - Rate this topic

How to: Connect to Azure SQL Database Using ADO.NET

Updated: December 6, 2013

Using ADO.NET to connect to a database in Microsoft Windows Azure SQL Database is similar to connecting to an instance of SQL Server on your premises. This topic describes a few considerations for connecting to Windows Azure SQL Database and provides an example console application that you can use to get started. For more general information about connecting to a data source with ADO.NET, see Connecting to a Data Source (ADO.NET).

Considerations

When connecting to a database in SQL Database with an ADO.NET application, consider the following points:

Known Issue When Connecting to SQL Database Using ADO.NET in .NET 4.0 and Earlier

The following error message is used in SqlClient versions older than .NET 4.5:

Step Name : Read Query on Instance Management DB \n System.Data.SqlClient.SqlException (0x80131904): The instance of SQL Server you attempted to connect to does not support encryption.
at System.Data.SqlClient.SqlInternalConnection.OnError(SqlException exception, Boolean breakConnection)
at System.Data.SqlClient.TdsParser.ThrowExceptionAndWarning() 
at System.Data.SqlClient.TdsParser.ConsumePreLoginHandshake(Boolean encrypt, Boolean trustServerCert, Boolean& marsCapable)
at System.Data.SqlClient.TdsParser.Connect(ServerInfo serverInfo, SqlInternalConnectionTds connHandler, Boolean ignoreSniOpenTimeout, Int64 timerExpire, Boolean encrypt, Boolean trustServerCert, Boolean integratedSecurity)
at System.Data.SqlClient.SqlInternalConnectionTds.AttemptOneLogin(ServerInfo serverInfo, String newPassword, Boolean ignoreSniOpenTimeout, TimeoutTimer timeout, SqlConnection owningObject)
at System.Data.SqlClient.SqlInternalConnectionTds.LoginNoFailover(ServerInfo serverInfo, String newPassword, Boolean redirectedUserInstance, SqlConnection owningObject, SqlConnectionString connectionOptions, TimeoutTimer timeout)

This error indicates a failure during the login process, and is not an encryption failure. Beginning in .NET 4.5, ADO.NET displays a better error message:

A connection was successfully established with the server, but then an error occurred during the pre-login handshake.

Console Application Example

The following example is a console application that connects to Windows Azure SQL Database. The console application performs the following steps:

  1. The console application uses a SqlConnectionStringBuilder object to connect to the master database in Windows Azure SQL Database. The application then creates a database whose name comes from the sampleDatabaseName string.

  2. Then, the console application uses a second SqlConnectionStringBuilder object to connect to the new database.

  3. Once connected, the console application uses the second SqlConnectionStringBuilder object to create a database table and perform a number of data manipulation language (DML) statements.

  4. Finally, the console application returns data to the console before and after data changes.

Using this Example

To use this example in Visual Studio with your SQL Database server, do the following steps:

  1. Open Visual Studio and create a console application.

  2. Replace the code in the program file with the code from this example.

  3. Replace <ProvideUserName> with the name of an Windows Azure SQL Database login that has been assigned the dbmanager role. Note: if you use the login@server username format, the server portion of the name must match the first part of the server's fully qualified name. For example, if your server is servername.database.windows.net, your login name is loginname@servername. For more information about Windows Azure SQL Database roles, see Managing Databases and Logins in Azure SQL Database.

  4. Replace <ProvidePassword> with the password associated with the login. Note: We recommend using a strong password when creating a login. For more information, see Strong Passwords.

  5. Replace <ProvideServerName> with the fully qualified domain name of your SQL Database server. For example: servername.database.windows.net

  6. Replace <ProvideDatabaseName> with the name of the database you want the code to create.

  7. Run the code.

noteNote
There are no Transact-SQL statements in this code to remove the new database. Delete the database before running this application again.


using System;
using System.Collections.Generic;
using System.Linq;
using System.Text;
using System.Data.SqlClient;
using System.Data;

namespace Microsoft.SDS.Samples
{
class Program
{
// Provide the following information
private static string userName = "<ProvideUserName>";
private static string password = "<ProvidePassword>";
private static string dataSource = "<ProvideServerName>";
private static string sampleDatabaseName = "<ProvideDatabaseName>";

static void Main(string[] args)
{
    // Create a connection string for the master database
    SqlConnectionStringBuilder connString1Builder;
    connString1Builder = new SqlConnectionStringBuilder();
    connString1Builder.DataSource = dataSource;
    connString1Builder.InitialCatalog = "master";
    connString1Builder.Encrypt = true;
    connString1Builder.TrustServerCertificate = false;
    connString1Builder.UserID = userName;
    connString1Builder.Password = password;

    // Create a connection string for the sample database
    SqlConnectionStringBuilder connString2Builder;
    connString2Builder = new SqlConnectionStringBuilder();
    connString2Builder.DataSource = dataSource;
    connString2Builder.InitialCatalog = sampleDatabaseName;
    connString2Builder.Encrypt = true;
    connString2Builder.TrustServerCertificate = false;
    connString2Builder.UserID = userName;
    connString2Builder.Password = password;

    // Connect to the master database and create the sample database
    using (SqlConnection conn = new SqlConnection(connString1Builder.ToString()))
    {
        using (SqlCommand command = conn.CreateCommand())
        {

            conn.Open();

            // Create the sample database
            string cmdText = String.Format("CREATE DATABASE {0}",
                                            sampleDatabaseName);
            command.CommandText = cmdText;
            command.ExecuteNonQuery();
            conn.Close();
        }
    }

    // Connect to the sample database and perform various operations
    using (SqlConnection conn = new SqlConnection(connString2Builder.ToString()))
    {
        using (SqlCommand command = conn.CreateCommand())
        {
            conn.Open();

            // Create a table
            command.CommandText = "CREATE TABLE T1(Col1 int primary key, Col2 varchar(20))";
            command.ExecuteNonQuery();

            // Insert sample records
            command.CommandText = "INSERT INTO T1 (col1, col2) values (1, 'string 1'), (2, 'string 2'), (3, 'string 3')";
            int rowsAdded = command.ExecuteNonQuery();

            // Query the table and print the results
            command.CommandText = "SELECT * FROM T1";

            using (SqlDataReader reader = command.ExecuteReader())
            {
                // Loop over the results
                while (reader.Read())
                {
                    Console.WriteLine("Col1: {0}, Col2: {1}", 
                                    reader["Col1"].ToString().Trim(), 
                                    reader["Col2"].ToString().Trim());
                }
            }

            // Update a record
            command.CommandText = "UPDATE T1 SET Col2='string 1111' WHERE Col1=1";
            command.ExecuteNonQuery();

            // Delete a record
            command.CommandText = "DELETE FROM T1 WHERE Col1=2";
            command.ExecuteNonQuery();

            // Query the table and print the results

            Console.WriteLine("\nAfter update/delete the table has these records...");

            command.CommandText = "SELECT * FROM T1";

            using (SqlDataReader reader = command.ExecuteReader())
            {
                // Loop over the results
                while (reader.Read())
                {
                    Console.WriteLine("Col1: {0}, Col2: {1}", 
                                    reader["Col1"].ToString().Trim(), 
                                    reader["Col2"].ToString().Trim());
                }
            }

            conn.Close();
        }
    }
    Console.WriteLine("Press enter to continue...");
    Console.ReadLine();
}
}
}

See Also

Did you find this helpful?
(1500 characters remaining)
Thank you for your feedback

Community Additions

ADD
Show:
© 2014 Microsoft. All rights reserved.