Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 8 additions & 0 deletions samples/features/sql-clr/RegEx/.gitignore
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
*.cproj.user
.vs/*
.vscode/*
bin/*
obj/*
*.log
Properties/PublishProfiles/*
SqlClrRegEx.sql
36 changes: 36 additions & 0 deletions samples/features/sql-clr/RegEx/Properties/AssemblyInfo.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
using System.Reflection;
using System.Runtime.CompilerServices;
using System.Runtime.InteropServices;

// General Information about an assembly is controlled through the following
// set of attributes. Change these attribute values to modify the information
// associated with an assembly.
[assembly: AssemblyTitle("SqlClrRegEx")]
[assembly: AssemblyDescription("")]
[assembly: AssemblyConfiguration("")]
[assembly: AssemblyCompany("")]
[assembly: AssemblyProduct("SqlClrRegEx")]
[assembly: AssemblyCopyright("Copyright © 2017")]
[assembly: AssemblyTrademark("")]
[assembly: AssemblyCulture("")]

// Setting ComVisible to false makes the types in this assembly not visible
// to COM components. If you need to access a type in this assembly from
// COM, set the ComVisible attribute to true on that type.
[assembly: ComVisible(false)]

// The following GUID is for the ID of the typelib if this project is exposed to COM
[assembly: Guid("265e0bc3-ad5f-44f3-bb17-c61f77b9847f")]

// Version information for an assembly consists of the following four values:
//
// Major Version
// Minor Version
// Build Number
// Revision
//
// You can specify all the values or you can default the Build and Revision Numbers
// by using the '*' as shown below:
// [assembly: AssemblyVersion("1.0.*")]
[assembly: AssemblyVersion("1.0.0.0")]
[assembly: AssemblyFileVersion("1.0.0.0")]
84 changes: 84 additions & 0 deletions samples/features/sql-clr/RegEx/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
# Implementing Regular Expressions in SQL Server using CLR UDF
SQL Database don't have built-in support for regular expressions, so the only workaround is to use Regular Expressions that exist in .Net framework and expose them as T-SQL functions.
This code sample demonstrates how to create CLR User-Defined functions that expose regular expression functionalities that exist in .Net framework.

### Contents

[About this sample](#about-this-sample)<br/>
[Build the CLR/RegEx functions](#build-functions)<br/>
[Add RegEx functions to your SQL database](#add-functions)<br/>
[Test the functions](#test)<br/>
[Disclaimers](#disclaimers)<br/>

<a name=about-this-sample></a>

## About this sample
1. **Applies to:** SQL Server 2005+ Enterprise / Developer / Evaluation Edition
2. **Key features:**
- CLR
3. **Programming Language:** .NET C#
4. **Author:** Jovan Popovic [jovanpop-msft]

<a name=build-functions></a>

## Build the CLR/RegEx functions

1. Download the source code and open the solution using Visual Studio.
2. Change the password in .pfk file and rebuild the solution in Retail mode.
3. Open and save SqlClrRegEx.tt to generate output T-SQL file that will contain script that inserts .dll file with the Regex functions, and exposes them as T-SQL/CLR functions.

<a name=add-functions></a>
## Add RegEx functions to your SQL database

File SqlClrRegEx.sql contains the code that will import functions into SQL Database.

If you have not added CLR assemblies in your database, you should use the following script to enable CLR:
```
sp_configure @configname=clr_enabled, @configvalue=1
GO
RECONFIGURE
GO
```

Once you enable CLR, you can use the T-SQL script to add the regex functions. The script depends on the location where you have built the project, and might look like:
```
--Create the assembly
CREATE ASSEMBLY SqlClrRegEx FROM 'D:\GitHub\sql-server-samples\samples\features\sql-clr\RegEx\bin\Release\SqlClrRegEx.dll' WITH PERMISSION_SET = SAFE
GO

CREATE SCHEMA REGEX;
GO

--Create the functions
CREATE FUNCTION REGEX.MATCH (@src NVARCHAR(MAX), @regex NVARCHAR(4000))
RETURNS BIT
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledMatch
GO
CREATE FUNCTION REGEX.SUBSTRING (@src NVARCHAR(MAX), @regex NVARCHAR(4000))
RETURNS NVARCHAR(4000)
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledSubstring
GO
CREATE FUNCTION REGEX.REPLACE (@src NVARCHAR(MAX), @regex NVARCHAR(MAX), @value NVARCHAR(4000))
RETURNS NVARCHAR(MAX)
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledReplace
GO
```

This code will import assembly in SQL Database and add three functions that provide RegEx functionalities.

<a name=test></a>

## Test the functions

Once you create the assembly and expose the functions, you can use regular expression functionalities in T-SQL code:

```
IF( REGEX.MATCH('tst123test', '[0-9]+') = 1 )
SELECT REGEX.SUBSTRING('tst123test', '[0-9]+'), REGEX.REPLACE('tst123test', '[0-9]+', 'XXX')
```

<a name=disclaimers></a>

## Disclaimers
The code included in this sample is not intended to be a set of best practices on how to build scalable enterprise grade applications. This is beyond the scope of this sample.

46 changes: 46 additions & 0 deletions samples/features/sql-clr/RegEx/RegEx.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
using Microsoft.SqlServer.Server;
using System.Text.RegularExpressions;

/// <summary>
/// https://blogs.msdn.microsoft.com/sqlclr/2005/06/29/working-with-regular-expressions/
/// </summary>
public partial class RegEx
{
[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static bool Match(string source, string pattern)
{
Regex r1 = new Regex(pattern);
return r1.Match(source).Success;
}

[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static bool CompiledMatch(string source, string pattern)
{
return Regex.Match(source, pattern, RegexOptions.Compiled).Success;
}

[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static string Substring(string source, string pattern)
{
Regex r1 = new Regex(pattern);
return r1.Match(source).Value;
}

[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static string CompiledSubstring(string source, string pattern)
{
return Regex.Match(source, pattern, RegexOptions.Compiled).Value;
}

[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static string Replace(string source, string pattern, string value)
{
return Regex.Replace(source, pattern, value);
}

[SqlFunction(IsDeterministic = true, IsPrecise = true)]
public static string CompiledReplace(string source, string pattern, string value)
{
return Regex.Replace(source, pattern, value, RegexOptions.Compiled);
}
};
68 changes: 68 additions & 0 deletions samples/features/sql-clr/RegEx/SqlClrRegEx.csproj
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
<?xml version="1.0" encoding="utf-8"?>
<Project ToolsVersion="15.0" xmlns="http://schemas.microsoft.com/developer/msbuild/2003">
<Import Project="$(MSBuildExtensionsPath)\$(MSBuildToolsVersion)\Microsoft.Common.props" Condition="Exists('$(MSBuildExtensionsPath)\$(MSBuildToolsVersion)\Microsoft.Common.props')" />
<PropertyGroup>
<Configuration Condition=" '$(Configuration)' == '' ">Debug</Configuration>
<Platform Condition=" '$(Platform)' == '' ">AnyCPU</Platform>
<ProjectGuid>{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}</ProjectGuid>
<OutputType>Library</OutputType>
<AppDesignerFolder>Properties</AppDesignerFolder>
<RootNamespace>SqlClrRegEx</RootNamespace>
<AssemblyName>SqlClrRegEx</AssemblyName>
<TargetFrameworkVersion>v4.6.1</TargetFrameworkVersion>
<FileAlignment>512</FileAlignment>
</PropertyGroup>
<PropertyGroup Condition=" '$(Configuration)|$(Platform)' == 'Debug|AnyCPU' ">
<DebugSymbols>true</DebugSymbols>
<DebugType>full</DebugType>
<Optimize>false</Optimize>
<OutputPath>bin\Debug\</OutputPath>
<DefineConstants>DEBUG;TRACE</DefineConstants>
<ErrorReport>prompt</ErrorReport>
<WarningLevel>4</WarningLevel>
</PropertyGroup>
<PropertyGroup Condition=" '$(Configuration)|$(Platform)' == 'Release|AnyCPU' ">
<DebugType>pdbonly</DebugType>
<Optimize>true</Optimize>
<OutputPath>bin\Release\</OutputPath>
<DefineConstants>TRACE</DefineConstants>
<ErrorReport>prompt</ErrorReport>
<WarningLevel>4</WarningLevel>
</PropertyGroup>
<PropertyGroup>
<SignAssembly>true</SignAssembly>
</PropertyGroup>
<PropertyGroup>
<AssemblyOriginatorKeyFile>SqlClrRegEx.pfx</AssemblyOriginatorKeyFile>
</PropertyGroup>
<ItemGroup>
<Reference Include="System" />
<Reference Include="System.Core" />
<Reference Include="System.Xml.Linq" />
<Reference Include="System.Data.DataSetExtensions" />
<Reference Include="Microsoft.CSharp" />
<Reference Include="System.Data" />
<Reference Include="System.Net.Http" />
<Reference Include="System.Xml" />
</ItemGroup>
<ItemGroup>
<Compile Include="Properties\AssemblyInfo.cs" />
<Content Include="SqlClrRegEx.sql">
<AutoGen>True</AutoGen>
<DesignTime>True</DesignTime>
<DependentUpon>SqlClrRegEx.tt</DependentUpon>
</Content>
<Content Include="SqlClrRegEx.tt">
<Generator>TextTemplatingFileGenerator</Generator>
<LastGenOutput>SqlClrRegEx.sql</LastGenOutput>
</Content>
<Compile Include="RegEx.cs" />
</ItemGroup>
<ItemGroup>
<None Include="SqlClrRegEx.pfx" />
</ItemGroup>
<ItemGroup>
<Service Include="{508349B6-6B84-4DF5-91F0-309BEEBAD82D}" />
</ItemGroup>
<Import Project="$(MSBuildToolsPath)\Microsoft.CSharp.targets" />
</Project>
Binary file added samples/features/sql-clr/RegEx/SqlClrRegEx.pfx
Binary file not shown.
25 changes: 25 additions & 0 deletions samples/features/sql-clr/RegEx/SqlClrRegEx.sln
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@

Microsoft Visual Studio Solution File, Format Version 12.00
# Visual Studio 15
VisualStudioVersion = 15.0.26730.16
MinimumVisualStudioVersion = 10.0.40219.1
Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "SqlClrRegEx", "SqlClrRegEx.csproj", "{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}"
EndProject
Global
GlobalSection(SolutionConfigurationPlatforms) = preSolution
Debug|Any CPU = Debug|Any CPU
Release|Any CPU = Release|Any CPU
EndGlobalSection
GlobalSection(ProjectConfigurationPlatforms) = postSolution
{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}.Debug|Any CPU.Build.0 = Debug|Any CPU
{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}.Release|Any CPU.ActiveCfg = Release|Any CPU
{265E0BC3-AD5F-44F3-BB17-C61F77B9847F}.Release|Any CPU.Build.0 = Release|Any CPU
EndGlobalSection
GlobalSection(SolutionProperties) = preSolution
HideSolutionNode = FALSE
EndGlobalSection
GlobalSection(ExtensibilityGlobals) = postSolution
SolutionGuid = {54C7E749-77A3-460D-A89A-5AB7943A1F15}
EndGlobalSection
EndGlobal
38 changes: 38 additions & 0 deletions samples/features/sql-clr/RegEx/SqlClrRegEx.tt
Original file line number Diff line number Diff line change
@@ -0,0 +1,38 @@
<#@output extension=".sql"#>
<#@ template language="C#" hostspecific="True" #>

--Drop the functions if they already exist
DROP FUNCTION IF EXISTS REGEX.MATCH
GO
DROP FUNCTION IF EXISTS REGEX.SUBSTRING
GO
DROP FUNCTION IF EXISTS REGEX.REPLACE
GO

DROP SCHEMA IF EXISTS REGEX;
GO

--Drop the assembly if it already exists
DROP ASSEMBLY IF EXISTS SqlClrRegEx
GO

--Create the assembly
CREATE ASSEMBLY SqlClrRegEx FROM '<#= this.Host.ResolvePath("bin\\Release\\SqlClrRegEx.dll") #>' WITH PERMISSION_SET = SAFE
GO

CREATE SCHEMA REGEX;
GO

--Create the functions
CREATE FUNCTION REGEX.MATCH (@src NVARCHAR(MAX), @regex NVARCHAR(4000))
RETURNS BIT
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledMatch
GO
CREATE FUNCTION REGEX.SUBSTRING (@src NVARCHAR(MAX), @regex NVARCHAR(4000))
RETURNS NVARCHAR(4000)
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledSubstring
GO
CREATE FUNCTION REGEX.REPLACE (@src NVARCHAR(MAX), @regex NVARCHAR(MAX), @value NVARCHAR(4000))
RETURNS NVARCHAR(MAX)
AS EXTERNAL NAME SqlClrRegEx.RegEx.CompiledReplace
GO