Get started with CLR integration
Applies to: SQL Server
This article provides an overview of the namespaces and libraries required to compile database objects using the Microsoft SQL Server integration with the .NET Framework common language runtime (CLR). The article also shows you how to write, compile, and run a small CLR stored procedure written in Microsoft Visual C# and Visual Basic.
Required namespaces
The components required to develop basic CLR database objects are installed with SQL Server. CLR integration functionality is exposed in an assembly called System.Data.dll
, which is part of the .NET Framework. This assembly can be found in the Global Assembly Cache (GAC) as well as in the .NET Framework directory. A reference to this assembly is typically added automatically by both command line tools and Microsoft Visual Studio, so there's no need to add it manually.
The System.Data.dll
assembly contains the following namespaces, which are required for compiling CLR database objects:
System.Data
System.Data.Sql
Microsoft.SqlServer.Server
System.Data.SqlTypes
Tip
Loading CLR database objects on Linux is supported, but they must be built with the .NET Framework (SQL Server CLR integration does not support .NET Core, or .NET 5 and later versions). Also, CLR assemblies with the EXTERNAL_ACCESS
or UNSAFE
permission set are not supported on Linux.
Write a "Hello World" stored procedure
Copy and paste the following Visual C# or Visual Basic code into a text editor, and save it in a file named helloworld.cs
or helloworld.vb
.
using System;
using System.Data;
using Microsoft.SqlServer.Server;
using System.Data.SqlTypes;
public class HelloWorldProc
{
[Microsoft.SqlServer.Server.SqlProcedure]
public static void HelloWorld(out string text)
{
SqlContext.Pipe.Send("Hello world!" + Environment.NewLine);
text = "Hello world!";
}
}
This program contains a single static method on a public class. This method uses two new classes, SqlContext and SqlPipe, for creating managed database objects to output a short text message. The method also assigns the string "Hello world!" as the value of an out
parameter. This method can be declared as a stored procedure in SQL Server, and then run in the same manner as a Transact-SQL stored procedure.
Compile this program as a library, load it into SQL Server, and run it as a stored procedure.
Compile the "Hello World" stored procedure
SQL Server installs the .NET Framework redistribution files by default. These files include csc.exe
and vbc.exe
, the command-line compilers for Visual C# and Visual Basic programs. In order to compile our sample, you must modify your path variable to point to the directory containing csc.exe
or vbc.exe
. The following path is the default installation path of the .NET Framework.
C:\Windows\Microsoft.NET\Framework\(version)
Version contains the version number of the installed .NET Framework. For example:
C:\Windows\Microsoft.NET\Framework\v4.8.0
Once you've added the .NET Framework directory to your path, you can compile the sample stored procedure into an assembly with the following command. The /target
option allows you to compile it into an assembly.
For Visual C# source files:
csc /target:library helloworld.cs
For Visual Basic source files:
vbc /target:library helloworld.vb
These commands launch the Visual C# or Visual Basic compiler using the /target
option to specify building a library DLL.
Load and run the "Hello World" stored procedure in SQL Server
Once the sample procedure has successfully compiled, you can test it in SQL Server. To do this, open SQL Server Management Studio and create a new query, connecting to a suitable test database (for example, the AdventureWorks
sample database).
The ability to execute common language runtime (CLR) code is set to OFF
by default in SQL Server. The CLR code can be enabled by using the sp_configure
system stored procedure. For more information, see Enabling CLR Integration.
We'll need to create the assembly so we can access the stored procedure. For this example, we'll assume that you've created the helloworld.dll
assembly in the C:\
directory. Add the following Transact-SQL statement to your query.
CREATE ASSEMBLY helloworld from 'C:\helloworld.dll' WITH PERMISSION_SET = SAFE
Once the assembly has been created, we can now access our HelloWorld method by using the create procedure statement. We'll call our stored procedure hello
:
CREATE PROCEDURE hello
@i nchar(25) OUTPUT
AS
EXTERNAL NAME helloworld.HelloWorldProc.HelloWorld;
-- if the HelloWorldProc class is inside a namespace (called MyNS),
-- the last line in the create procedure statement would be
-- EXTERNAL NAME helloworld.[MyNS.HelloWorldProc].HelloWorld
Once the procedure has been created, it can be run just like a normal stored procedure written in Transact-SQL. Execute the following command:
DECLARE @J NCHAR(25);
EXEC hello @J out;
PRINT @J;
This should result in the following output in the SQL Server Management Studio messages window.
Hello world!
Hello world!
Remove the "Hello World" stored procedure sample
When you're finished running the sample stored procedure, you can remove the procedure and the assembly from your test database.
First, remove the procedure using the drop procedure command.
IF EXISTS (SELECT name FROM sysobjects WHERE name = 'hello')
DROP PROCEDURE hello;
Once the procedure has been dropped, you can remove the assembly containing your sample code.
IF EXISTS (SELECT name FROM sys.assemblies WHERE name = 'helloworld')
DROP ASSEMBLY helloworld;
Next steps
For more information about CLR integration in SQL Server, see the following articles: