Click here to Skip to main content
65,938 articles
CodeProject is changing. Read more.
Articles / Languages / SQL

SQL CLR Functions

4.89/5 (16 votes)
20 Mar 2015CPOL3 min read 89.5K  
SQL CLR functions

Introduction

In this tip, we are going to create an assembly using .NET managed code to encrypt and decrypt a string. After that, we will use the same assembly to create a CLR function in SQL server as a scalar function.

We can create a function within SQL Server that depends on a SQL assembly which itself is compiled using any of the .NET framework Common Language Runtime (CLR) managed code.

Beginning with SQL Server 2005, we can write user-defined functions which are of scalar (which returns single value) and table-valued function types. However, in this blog post, we are dealing with Scalar type CLR functions.

T-SQL has a lot of inbuilt functions and features. However to custom our own complex logic, we use any CLR managed code like C# or VB.NET, etc., and incorporate it in SQL environment.

Here are the steps to create Scalar CLR functions:

Create a project of type "Class Library" using Visual Studio.

Add your static methods. In our case, "Encrypt" and "Decrypt” methods.

Image 1

Specify "SqlFunction()" attribute to all the functions that need to be accessed from SQL Server. This attribute can be found in "Microsoft.SqlServer.Server" namespace.

Compile & build the application in "Release" mode to get the assembly (.dll) from the Bin folder.

Now go to SQL Server MS; select your database and create New Query and execute the following statements below to enable CLR:

SQL
sp_configure 'clr enabled', 1;
GO
reconfigure
GO 

If you encounter any compatibility level errors, then check to see your database compatibility level using:

SQL
sp_dbcmptlevel 

If it is set to 100 or above, execute the following statement to set it to 90.

SQL
sp_dbcmptlevel 'SQLCLR', 90 

Before adding the 'DLL' to the SQL assemblies, you need to set the database to trustworthy. This can be used to reduce threats that can exist as a result of attaching a database that contains (malicious) assemblies with an EXTERNAL_ACCESS or UNSAFE permission setting:

SQL
ALTER DATABASE SET TRUSTWORTHY ON 

Now expand your database node to go to "Assemblies" located under "Programmability" and create a new assembly.

Image 2

Browse the DLL path from the Bin/Release folder.

Note: Assembly name will pick automatically from the imported DLL file.

Image 3

Now, click the button next to Assembly owner to select the appropriate owner from the existing user list. From the "Select Assembly Owner" window, click browse... button to see all list of owners. Select appropriate names (In my case, I chose "dbo" user) from the list and click OK.

Image 4

Next, we need to set valid permissions. As we are using static "Encrypt" and "Decrypt" methods, we need to set the permissions to "Unrestricted" mode as shown below:

Image 5

If everything works well, you will see an assembly created within Assemblies node.

(Note: In case you get any errors, check the steps #5, #6 and #7.)

So far, most of the work is done. All we need to do now is to create two scalar functions under "Functions/Scalar-valued Functions" node. We will create <font face="Courier New">Encrypt</font> and <font face="Courier New">Decrypt</font> functions in SQL Server with an external name specific to the assembly namespace. Execute the following query to create external names:

SQL
CREATE FUNCTION [dbo].Encrypt(@Input nvarchar(max)) RETURNS nvarchar(max)
EXTERNAL NAME  EDCLR.EDCLR.Encrypt
Go 
CREATE FUNCTION [dbo].Decrypt(@Input nvarchar(max)) RETURNS nvarchar(max)
EXTERNAL NAME EDCLR.EDCLR.Decrypt; 

Image 6

When everything is ready, use the following query to Encrypt the given string:

SQL
Select dbo.Encrypt('Hello World') 

and use function to Decrypt the given encrypted string:

SQL
Select dbo.Decrypt('i9E2KOEoT7D+Doc2CBdjDA==') 

These scalar functions can be used to encrypt any sensitive information within SQL without depending on the code. Visit MSDN to know more about CLR functions.

Points of Interest

Make sure you reconfigure your database to enable CLR.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)