CLR Integration

  • Very true, and that is one of the reasons I see why it is important for more or less every DBA to at least have a basic understanding of what CLR Integration is and how it works. The code itself is normally not that difficult to read, so if it is just a rev iew to allow the code in the database most should get by. Writing it is of course more difficult. I think one of the concerns will be just how to look at the code, using Visual Studio (or other tool) etc.

    Hopefully we will see developers and DBAs working closer to solve these issues.

  • Even though I have some understanding of regular expressions, I did not write that one myself. I think I found it at Regular-Expressions.info, a very good resource.

  • Well, it installs on systems that do not have the .Net Framework installed already. But then it would be installed by the SQL Server 2005 installation. Note that it is the .Net Framework 2.0 (currently in beta) we are referring to here.

    Hopefully I will be exploring performance hits and requirements later, though I anticipate it will be a couple of articles from now.

  • My opinion is that it will be beneficial to have a "procedural language" available to perform functions that TSQL is not as adept at.  That is available today on the client side, obviously, but not quite so close to the data itself.  This will most likely create opportunities to make faster data access available to the other application tiers.

    Now, I'm not ready to go all chicken little and claim that C# will ruin my database, because it is not the best tool for getting data in and out of a database *in the general case*.  I don't believe that the presentation tier guys are going to ask for CLR in the database because they are used to having the recordsets handed to them ready-to-go.  What I do see is that I can find a better (faster) way to get them data in very specialized cases and for that I shall be eternally grateful.

    We'll see what happens...

    jg

     

  • I entirely agree.  In fact, I've just returned from a T-SQL course with Learning Tree and so am very pro T-SQL at the moment.  I think in the interim it'll be a case of finding my (and everybody else's) feet to discover which procedures are going to perform better depending on what language they're written in.

  • I think the one thing missing in this discussion is that although when used for the correct purposes CLR integration will prove addition to sql server it still falls foul of the same performance hit that you get with xprocs.

    This is because the UMS's in sql server works in a non-preemptive mode i.e. it is a co-operative scheduler and the functions to yield are not available to external applications that is if you could trust them to yield when they should so to schedule a CLR assembly sql passes the thread to to the windows scheduler so that it can be scheduled pre-emptively and then starts up a new thread to handle the work of the sscheduler object from which the thread was taken.

    This all involves context and keranl switching it's even worse if it then needs to acces the oDS layer as this involves more context switching etc.

    Regards

    David

  • David --

    Although SQL Server 2005 still schedules preemtively, UMS is gone (see: http://blogs.msdn.com/slavao/archive/2005/02/05/367816.aspx ). I believe SQLOS is supposed to handle context switching and other problems a lot more elegantly than UMS.

    --
    Adam Machanic
    whoisactive

  • My understanding from Ken Henderson's blog and is that this will still be an issue in 2005 but by the sound of slava's blog maybe not as bad hmm looks like we could be waiting on Ken's or Kalen's book on 2005 to clarify just what the performance issues are if any in using CLR for stored procs.

    Anyway ta for the link it was an interesting read.

  • I thought the article and example are quite interesting...but... what is the significance of " [Microsoft.SqlServer.Server.SqlFunction]" in

                  public partial class UserDefinedFunctions

                  {

                   [Microsoft.SqlServer.Server.SqlFunction]

     

    That, in summary, is a problem for me. I know sql better than .NET, be it VB.NET of C#.

     

    Bill

     

  • SqlFunctionAttribute is an attribute that marks a method as a function -- so that SQL Server knows how you intend to use the method.

    For more information on attributes, see:

    http://insight.zdnet.co.uk/software/applications/0,39020466,2118655,00.htm

    --
    Adam Machanic
    whoisactive

  • I realize that the Sql Server Project Template is only available in the Professional edition of VS but wouldn't it be possible to create a CLR proc by just creating a class library and somehow deploying it manually?

    "What I lack in youth I make up for in immaturity!"
    Please visit my music site at http://woundedego.com

  • billross (6/22/2008)


    I realize that the Sql Server Project Template is only available in the Professional edition of VS but wouldn't it be possible to create a CLR proc by just creating a class library and somehow deploying it manually?

    Absolutely. Compile your DLL, then use CREATE ASSEMBLY to register it with your database. Once you've done that you can use CREATE PROCEDURE, CREATE FUNCTION, etc, with the EXTERNAL NAME option to map your procedures, functions, etc, to the methods in the assembly.

    --
    Adam Machanic
    whoisactive

  • Thanks for the reply. I've been successful and for the benefit of others who want to do this, I illustrate your steps with an example from my application....

    First, I enable CLR:

    -- enable/disable the CLR

    sp_configure 'show advanced options', 1;

    GO

    RECONFIGURE;

    GO

    --sp_configure 'clr enabled', 0; -- disable

    sp_configure 'clr enabled', 1; -- enable

    GO

    RECONFIGURE;

    GO

    >>>>Compile your DLL

    Ok, this is my DLL:

    CTSStoredProcs.cs

    using System.Data.SqlTypes;

    using System.Text.RegularExpressions;

    using Microsoft.SqlServer.Server;

    public partial class CTSStoredProcs

    {

    [Microsoft.SqlServer.Server.SqlFunction]

    public static SqlBoolean RegExValidate(

    SqlString expressionToValidate, SqlString regularExpression)

    {

    Regex regex = new Regex(regularExpression.Value);

    return regex.IsMatch(expressionToValidate.Value);

    }

    }

    I got a clean build.

    >>>then use CREATE ASSEMBLY to register it with your database.

    Here is my Create Assembly script:

    CREATE ASSEMBLY CTSWebStoredProcs

    FROM 'C:\Projects\CTSWebClassLibrary\bin\Debug\CtsWebClassLibrary.dll'

    WITH PERMISSION_SET = SAFE;

    GO

    This runs and I get an entry in my Assemblies of CTSWebStoredProcs.

    >>>>Once you've done that you can use CREATE PROCEDURE, CREATE FUNCTION, etc, with the EXTERNAL NAME option to map your procedures, functions, etc, to the methods in the assembly.

    Here is my CREATE FUNCTION:

    CREATE FUNCTION dbo.RegExValidate

    (@expressionToValidate nVarChar(100),

    @regularExpressionparameter_name nVarChar(100))

    RETURNS bit

    EXTERNAL NAME CTSWebStoredProcs.CTSStoredProcs.RegExValidate

    I now have an entry in my Scalar Functions of dbo.RegExValidate.

    When I call the example, it validates perfectly:

    DROP TABLE dbo.PEOPLE

    GO

    CREATE TABLE dbo.PEOPLE (

    name VARCHAR(25) NOT NULL

    , emailaddress VARCHAR(255) NOT NULL

    , CONSTRAINT PEOPLE_ck_validemailaddress

    CHECK ( dbo.RegExValidate( emailaddress, N'^([\w-\.]+)@((\[[0-9]{1,3}\.[0-9]{1,3}\.[0-9]{1,3}\.)|(([\w-]+\.)+))([a-zA-Z]{2,4}|[0-9]{1,3})(\]?)$' ) = 1 )

    )

    go

    DECLARE @regex NVARCHAR(100)

    SET @regex = N'^([\w-\.]+)@((\[[0-9]{1,3}\.[0-9]{1,3}\.[0-9]{1,3}\.)|(([\w-]+\.)+))([a-zA-Z]{2,4}|[0-9]{1,3})(\]?)$'

    SELECT name, emailaddress, dbo.RegExValidate( emailaddress, @regex ) AS validemail FROM dbo.PEOPLE

    go

    Fantastic - thanks!

    "What I lack in youth I make up for in immaturity!"
    Please visit my music site at http://woundedego.com

  • Looks good, but you might want to apply the IsDeterministic and IsPrecise options on the SqlFunctionAttribute so that you can use your function in a wider variety of scenarios (such as a persisted computed column or an indexed view).

    --
    Adam Machanic
    whoisactive

  • Thanks. I wonder if you could show me how to do it. I tried this:

    CREATE FUNCTION dbo.RegExValidate

    (@expressionToValidate nVarChar(100),

    @regularExpressionparameter_name nVarChar(100))

    RETURNS bit

    WITH IsDeterministic, IsPrecise

    EXTERNAL NAME CTSWebStoredProcs.CTSStoredProcs.RegExValidate

    GO

    I didn't get squiggly lines, but when it ran it said that IsDeterministic is not a recognized option.

    "What I lack in youth I make up for in immaturity!"
    Please visit my music site at http://woundedego.com

Viewing 15 posts - 16 through 30 (of 31 total)

You must be logged in to reply to this topic. Login to reply