3

There exist some blog posts about how to use F# with SQLCLR in SQL Server that are helpful: http://richardminerich.com/2015/12/a-safer-way-to-use-f-with-sql-clr/, http://thelastexpression.blogspot.com/2012/04/f-agents-and-sqlclr.html, https://rojepp.wordpress.com/2011/08/03/f_on_sqlclr/, Can the F# core libs be SQLCLR-approved? and for the C# approach: http://www.sqlservercentral.com/Authors/Articles/Solomon_Rutzky/294002/

I am wondering/hoping that with the passage of time there is a blog post out there, which I haven't been able to find yet or an answer here, which addresses how to use F# with SQLCLR such that the assembly can be scripted into hex using Visual Studio (or some other tool), like is done with C# deployment (I don't have access to install code on the server except through SQL Server Management Studio), and is at least more safe than using 'trustworthy on' or 'unsafe'. I've written F# and lots of T-SQL before and the prototype I wrote (which now must live in SQL Server) in Common Lisp would map better to F# (and make me happier than using C#).

Community
  • 1
  • 1
Joe
  • 965
  • 11
  • 16
  • https://rojepp.wordpress.com/2011/08/03/f_on_sqlclr/ is also relevant – Joe Apr 05 '17 at 04:13
  • This adds to the discussion as well: http://stackoverflow.com/questions/5653963/how-is-a-clr-table-valued-function-streaming (see comments about how FSharp.Core is registered as an assembly) – Joe Apr 05 '17 at 04:55
  • Code referenced in the first comment above: https://bitbucket.org/rojepp/blogsqlclr/src/c9ebace12da4552076955a5029f10f288f943e90/SqlClr/Deploy.sql?at=default&fileviewer=file-view-default – Joe Apr 05 '17 at 05:12
  • This is also useful: http://serverfault.com/questions/323014/how-to-update-a-clr-assembly-without-dropping-assembly-from-sql-server – Joe Apr 08 '17 at 22:54

1 Answers1

3

I'm skeptical of the approach shown in your first link ( http://richardminerich.com/2015/12/a-safer-way-to-use-f-with-sql-clr/ ) as it does not directly show the loading of the FSharp.Core library, hence it is not clear that the author did not have to set TRUSTWORTHY ON in order to at least get that part working. What seems highly suspicious is that in Step 5, the Asymmetric Key-based Login is granted the wrong permission:

GRANT EXTERNAL ACCESS ASSEMBLY TO FSHARP_CLR_Login

Granting EXTERNAL ACCESS ASSEMBLY does not allow for setting an Assembly to UNSAFE. That requires the UNSAFE ASSEMBLY permission. It could be a copy / paste error when writing the post, but no proof is shown (i.e. from sys.databases) that TRUSTWORTHY is currently OFF, or that the author's code wasn't working prior to creating that Login and granting that permission to it.

So, I just tried this by installing the most recent build of FSharp.Core – 4.1.2 – and here is what I found:

  1. Confirm that TRUSTWORTHY is OFF (i.e. 0) via:

    SELECT [name], is_trustworthy_on FROM sys.databases WHERE [database_id] = DB_ID();
    
  2. Attempt to load FSharp.Core as SAFE, just to see if it works:

    USE [TestDB];
    
    CREATE ASSEMBLY [FSharp.Core]
    FROM N'C:\path\to\project\packages\FSharp.Core.4.1.2\lib\net45\FSharp.Core.dll'
    WITH PERMISSION_SET = SAFE;
    

    That receives the following error:

    Msg 6211, Level 16, State 1, Line 32
    CREATE ASSEMBLY failed because type 'Microsoft.FSharp.Collections.FSharpMap`2' in safe assembly 'FSharp.Core' has a static field 'empty'. Attributes of static fields in safe assemblies must be marked readonly in Visual C#, ReadOnly in Visual Basic, or initonly in Visual C++ and intermediate language.

  3. Attempt to load FSharp.Core again, but as UNSAFE:

    USE [TestDB];
    
    CREATE ASSEMBLY [FSharp.Core]
    FROM N'C:\path\to\project\packages\FSharp.Core.4.1.2\lib\net45\FSharp.Core.dll'
    WITH PERMISSION_SET = UNSAFE;
    

    That works. But, I didn't set the Database to TRUSTWORTHY ON, nor did I create a Login and grant it the EXTERNAL ACCESS ASSEMBLY permission. Meaning: the violation is probably found via a run-time verification instead of a load-time verification. And I have no way to test beyond this part, but I would expect that an error will occur.

  4. If an error does occur regarding the UNSAFE Permission Set for this Assembly, then you can handle that without resorting to setting TRUSTWORTHY ON, but you will need to create a Certificate in master and a Certficate-based Login:

    USE [master];
    
    CREATE CERTIFICATE [FSharpCert45]
    FROM EXECUTABLE FILE =
            N'C:\path\to\project\packages\FSharp.Core.4.1.2\lib\net45\FSharp.Core.dll';
    
    CREATE LOGIN [FSharpLogin45] FROM CERTIFICATE [FSharpCert45];
    
    GRANT UNSAFE ASSEMBLY TO [FSharpLogin45];
    
  5. IF your Assembly is also required to be marked as UNSAFE, then you can create an Asymmetric Key from the DLL in master and then a Key-based Login from that Asymmetric Key, and then grant that Key-based Login the UNSAFE ASSEMBLY permission. (this assumes that your Assembly is signed -- and protected with a password)

  6. Of course, all of the above assumes that you can get the DLL onto the server or at least onto a share that the SQL Server service account has access to, and you did mention wanting to deploy this via hex bytes. That should be possible by doing:

    1. In Visual Studio, under "References" in the "Solution Explorer", go to the "Properties" for FSharp.Core and set Model Aware to True and Permission Set to Unsafe. This will cause the publish process to include the DLL in the build script.
    2. If the DLL is already in your target DB, then it probably won't generate the CREATE ASSEMBLY statement for this Assembly since publish scripts are incremental changes. If this is the case, then go to the project properties, and under Project Settings, check the box for Create script (.sql file) (if not already checked). This will cause the build process to always produce a _Create.sql script, and in there will definitely be the CREATE ASSEMBLY statement for FSharp.Core.
    3. That CREATE ASSEMBLY [FSharp.Core] FROM 0x... statement will obviously be used to load the Assembly into the target DB (i.e. where your Assembly is also getting loaded into).
    4. That CREATE ASSEMBLY [FSharp.Core] FROM 0x... statement will also be your ticket to creating the objects in master as follows:

      USE [master];
      
      CREATE ASSEMBLY [FSharp.Core]
      FROM 0x4D....
      WITH PERMISSION_SET = UNSAFE;
      
      CREATE CERTIFICATE [FSharpCert45]
      FROM ASSEMBLY [FSharp.Core];
      
      DROP ASSEMBLY [FSharp.Core];
      
      CREATE LOGIN [FSharpLogin45] FROM CERTIFICATE [FSharpCert45];
      
      GRANT UNSAFE ASSEMBLY TO [FSharpLogin45];
      

      This worked for me on SQL Server 2012, the only difference being I used the file path instead of the hex bytes.

Solomon Rutzky
  • 46,688
  • 9
  • 128
  • 171
  • 2
    Thanks so much @srutzky for looking into it and thank you for your excellent Stairway series. – Joe Apr 05 '17 at 00:01
  • @Joe You are quite welcome, and thank you for those kind words. I am glad that people are getting something out of those articles (which I should soon be adding to). I have updated my answer now that I have had a chance to test (at least as far as I could go without doing an actual F# project, so your feedback here would be much appreciated :-). – Solomon Rutzky Apr 05 '17 at 03:37
  • Outstanding analysis, thank you! I hope to try this out very soon. – Joe Apr 05 '17 at 04:17
  • Under step 6.1 above, in my project in VS Community Edition, I don't have the Model Aware property available on FSharp.Core reference. I suspect that this may because of how the project was instantiated as an F# project to which I have added the sql files necessary. I will try it as an SQL CLR C# project and add to that F# files. This would give me access to the database creation "new item" choice too I suppose. I need to run this against a local db so that I can then get hex for the assemblies and then finally run it against the remote sql server (to which I don't have file access). – Joe Apr 13 '17 at 02:57
  • 1
    @Joe You don't need to run it anywhere to get the hex bytes for the `CREATE ASSEMBLY` statement. Just make sure "Create Script" check-box is checked and then just do a build. No need to deploy / publish. That will generated the `_create.sql` script that has the DROP / CREATE DATABASE and then all of the CREATE statements, with all Assemblies being `FROM 0x....`. – Solomon Rutzky Apr 13 '17 at 05:33
  • Do you know if there is a way to generate the hex bytes from the command line instead of relying on VS or SSMS? If it is the literal hex bytes that VS or SSMS generates, then I would think this might be possible. It would be a great workflow for my particular situation. – Joe Apr 22 '17 at 03:12
  • I found http://stackoverflow.com/questions/2885335/clr-sql-assembly-get-the-bytestream which should do the trick hopefully – Joe Apr 22 '17 at 03:14
  • @Joe Yes, I have a utility to do just that, including breaking the hex bytes "string" into multiple lines so that it is handled better in SSMS. I can try to post it to GitHub this weekend...have been meaning to for a long time now anyway.. – Solomon Rutzky Apr 22 '17 at 04:05
  • That would be great, thanks srutzky. I just tested the code I referenced and it worked well. I did have to prepend 0x to the output for literal hex representation. This method just produces one really long string (which isn't really a problem), so yours would be good to see. What is nice about this is that I can and did use mono to generate this. I hope to move the whole process onto mono, the only trick left to doing so is to try referencing the assemblies needed: I'll copy them from my Windows VM onto my mac and then reference them from the command line. I prefer unix, so this would be ideal – Joe Apr 22 '17 at 04:11
  • I just ran into: 'CREATE ASSEMBLY for assembly 'FSharp.Core' failed because assembly 'FSharp.Core' is not authorized for PERMISSION_SET = UNSAFE. The assembly is authorized when either of the following is true: the database owner (DBO) has UNSAFE ASSEMBLY permission and the database has the TRUSTWORTHY database property on; or the assembly is signed with a certificate or an asymmetric key that has a corresponding login with UNSAFE ASSEMBLY permission.' when I run the example code you kindly provided to create a certificate. To me it looks like a chicken-egg problem. – Joe Apr 22 '17 at 04:17
  • There is also a warning above that, which is duly noted: Warning: The Microsoft .NET Framework assembly 'fsharp.core, version=4.4.1.0, culture=neutral, publickeytoken=b03f5f7f11d50a3a, processorarchitecture=msil.' you are registering is not fully tested in the SQL Server hosted environment and is not supported. In the future, if you upgrade or service this assembly or the .NET Framework, your CLR integration routine may stop working. Please refer SQL Server Books Online for more details. – Joe Apr 22 '17 at 04:23
  • I may just use C#, but retain the workflow I am developing with mono. Presumably, I haven't test it yet, csharp dll is already installed in the 2012 sql server I am working against, so I would only have to deploy hex bytes for my own assembly. – Joe Apr 22 '17 at 04:24
  • 1
    @Joe Yes, you probably need to set the DB to `TRUSTWORTHY ON` in order to load the `FSharp.Core` assembly. But also yes, C#, as long as the libraries you need to reference are included in the "supported" list (and are hence pre-loaded into SQL Server CLR Host), then that should be a more stable approach. – Solomon Rutzky Apr 22 '17 at 04:30
  • Thanks for the quick response and info about supported libraries. I'll look up what libraries are supported. – Joe Apr 22 '17 at 04:32
  • Here it is: https://sqljunkieshare.com/2012/02/22/list-of-supported-librariesnamespaces-by-clr-integration-in-sql-server-2008r2-and-2012/ and same thing here from the official source (though no mention of which version of sql server in this last link): https://learn.microsoft.com/en-us/sql/relational-databases/clr-integration/database-objects/supported-net-framework-libraries – Joe Apr 22 '17 at 04:34
  • 1
    @Joe I was about to paste in the proper link when you posted that last comment. After reviewing it and another SQLCLR article on that site I would caution against relying upon their info. Here is the primary source for the list: https://docs.microsoft.com/en-us/sql/relational-databases/clr-integration/database-objects/supported-net-framework-libraries for other info on SQLCLR, please see the series I am writing on this topic on SQL Server Central (which you linked in the question ;): [Stairway to SQLCLR](http://www.sqlservercentral.com/stairway/105855/) (that site requires free registration). – Solomon Rutzky Apr 22 '17 at 04:38
  • 1
    I just noticed that you had updated your last comment with the official link. The list of assemblies is for SQL Server 2008 and newer...SQL Server 2005 was missing the bottom two: **System.Core.dll** and **System.Xml.Linq.dll**. – Solomon Rutzky Apr 22 '17 at 04:48