Export (0) Print
Expand All
15 out of 63 rated this helpful - Rate this topic

How to: Create and Run a CLR SQL Server Stored Procedure 

Create SQL stored procedures by adding Stored Procedure items to SQL Server projects. After successfully deploying to a SQL Server, stored procedures created in managed code are called and executed like any other stored procedures.

NoteNote

The common language runtime (CLR) integration feature is off by default in Microsoft SQL Server and must be enabled in order to use SQL Server project items. To enable CLR integration, use the clr enabled option of the sp_configure stored procedure. From more information, see Enabling CLR Integration.

NoteNote

The dialog boxes and menu commands you see might differ from those described in Help depending on your active settings or edition. To change your settings, choose Import and Export Settings on the Tools menu. For more information, see Visual Studio Settings.

Creating SQL Server Stored Procedures

To create a SQL Server stored procedure

  1. Open an existing SQL Server Project, or create a new one. For more information, see How to: Create a SQL Server Project.

  2. From the Project menu, select Add New Item.

  3. Select Stored Procedure in the Add New Item Dialog Box.

  4. Type a Name for the new stored procedure.

  5. Add code to run when the stored procedure is executed. See the example below.

NoteNote

C++ examples must be compiled with the /clr:safe compiler option.

  1. For Visual Basic and Visual C#, in Solution Explorer, open the TestScripts folder and double-click the Test.sql file.

    For Visual C++, in Solution Explorer, open the debug.sql file.

  2. Add code to the Test.sql (debug.sql for Visual C++) file to execute the stored procedure. See the second example below.

  3. Press F5 to build, deploy, and debug the stored procedure. For information on deploying without debugging, see How to: Deploy SQL Server Project Items to a SQL Server.

  4. View the results in the Output Window and select Show output from: Database Output.

Example

The following code example creates a stored procedure that inserts a record into the Currency table of the Adventure Works sample database. After creating the stored procedure, deploy it to the SQL Server. For more information, see How to: Deploy SQL Server Project Items to a SQL Server.

using System;
using System.Data;
using System.Data.SqlClient;
using System.Data.SqlTypes;
using Microsoft.SqlServer.Server;


public partial class StoredProcedures
{
    [SqlProcedure()]
    public static void InsertCurrency_CS(
        SqlString currencyCode, SqlString name)
    {
        using (SqlConnection conn = new SqlConnection("context connection=true"))
        {
            SqlCommand InsertCurrencyCommand = new SqlCommand();
            SqlParameter currencyCodeParam = new SqlParameter("@CurrencyCode", SqlDbType.NVarChar);
            SqlParameter nameParam = new SqlParameter("@Name", SqlDbType.NVarChar);



            InsertCurrencyCommand.CommandText =
                "INSERT Sales.Currency (CurrencyCode, Name, ModifiedDate)" +
                " VALUES(@CurrencyCode, @Name)";

            InsertCurrencyCommand.Connection = conn;

            conn.Open();
            InsertCurrencyCommand.ExecuteNonQuery();
            conn.Close();
        }
    }
}

Add code to execute and test your stored procedure to the Test.sql (debug.sql in Visual C++) file in the TestScripts folder in your project. For example, if you deployed a stored procedure, run it by calling EXEC <StoredProcedureName> and passing in any expected parameters. If your stored procedure does not return any values, insert additional code to verify data was affected by the stored procedure.

EXEC InsertCurrency 'AAA', 'Currency Test'
SELECT * from Sales.Currency where CurrencyCode = 'AAA'

See Also

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

Community Additions

ADD
Show:
© 2014 Microsoft. All rights reserved.