February 4, 2009 at 11:24 pm
Comments posted to this topic are about the item Trading in xp_cmdshell for SQLCLR (Part 1) - List Directory Contents
Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
My Blog | Twitter | MVP Profile
Training | Consulting | Become a SQLskills Insider
Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]
February 5, 2009 at 1:08 am
Thanks Jonathan for this very timely article! Can you advise whether this CLR function will work for UNC paths?
Thanks,
Carleton
February 5, 2009 at 2:06 am
I thought the install script for this CLR routine was nicely done, and very useful. The Asymmetric Key side is so often left out.
I can see why a CLR routine is better than your xp_cmdshell routine. As I see it, it will only work on specific version of the operating system, with a specific date format. Surely, anyone actually trying to use this code will get in a pickle. Another problem you'll come across is the nesting of the INSERT INTO ... EXEC. It seems unfair to use it as a comparison to the CLR routine, since there are ways around the specificity of the code.
I'm puzzling over the CLR routine. I can't see how you handle the exception that happens when an invalid path is passed to DirectoryInfo. As far as I can see, a NET exception is thrown and just falls back into SQL Server. How does the calling code handle this? The DOS version will politely send back a 'file not found' (depending on language setting etc.) but your CLR routine would surely just barf. Am I missing something?
Best wishes,
Phil Factor
February 5, 2009 at 2:18 am
Carleton (2/5/2009)
Thanks Jonathan for this very timely article! Can you advise whether this CLR function will work for UNC paths?Thanks,
Carleton
As long as the SQL Service Account has access to the UNC path, yes. If security needs further abstraction, a windows user could be explicitly impersonated in code to allow only specific users access to the UNC paths as well.
Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
My Blog | Twitter | MVP Profile
Training | Consulting | Become a SQLskills Insider
Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]
February 5, 2009 at 2:20 am
Phil Factor (2/5/2009)
I thought the install script for this CLR routine was nicely done, and very useful. The Asymmetric Key side is so often left out.I can see why a CLR routine is better than your xp_cmdshell routine. As I see it, it will only work on specific version of the operating system, with a specific date format. Surely, anyone actually trying to use this code will get in a pickle. Another problem you'll come across is the nesting of the INSERT INTO ... EXEC. It seems unfair to use it as a comparison to the CLR routine, since there are ways around the specificity of the code.
I'm puzzling over the CLR routine. I can't see how you handle the exception that happens when an invalid path is passed to DirectoryInfo. As far as I can see, a NET exception is thrown and just falls back into SQL Server. How does the calling code handle this? The DOS version will politely send back a 'file not found' (depending on language setting etc.) but your CLR routine would surely just barf. Am I missing something?
Phil,
Since I never write bad code, I would never provide it a bad path. 😉
Actually you raise a good point and I'll take a look at how to make it smarter and provide an update script here in comments later on.
Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
My Blog | Twitter | MVP Profile
Training | Consulting | Become a SQLskills Insider
Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]
February 5, 2009 at 5:04 am
What is the name for the window with horizontal scroll bar in which the code is presented? Text of article -- window with code -- more article text -- another window ... In every article on sqlservercentral.com that I have read that uses the windows to present code, the windows display less than an inch wide and can't be stretched. Scrolling doesn't help when the window displays less than an inch at a time. Is this window method of setting off the code within the article discussion an improvement on simply using whitespace and switching between fonts? No.
I haven't copied the code from each of the windows and pasted it into a document where I can read it, so I haven't learned from this article. It is CLR, though, that use of CLR makes it harder for a SQL Server administrator to see what's going on with their SQL Server. A SQL Server administrator can see instantly whether xp_cmdshell is enabled, knows the implications of this, and can use T-SQL to find all stored procs with the string 'xp_cmdshell'. Security decisions that aren't transparent to the SQL Server administrator two years down the road when the clever application developer has gone elsewhere are not usually supported. If an application feature causes problems because the administrator doesn't understand it, they often rewrite that feature, calling the rewrite a patch.
_________________
"Look, those sheep have been shorn."
data analyst replies, "On the sides that we can see.."
February 5, 2009 at 5:22 am
use of CLR makes it harder for a SQL Server administrator to see what's going on with their SQL Server.
Yes, Agreed! However, I've recently started using NET Reflector with an add-in that allows you to see the source of all the CLR routines currently in the database.
http://www.denisbauer.com/NETTools/SQL2005Browser.aspx
It is a joy to use and it means that the D**ned developers can't hide their code from you, particularly as you can decompile it into VB or C#. and save the source to a file. Power to the DBA!
Best wishes,
Phil Factor
February 5, 2009 at 5:52 am
Thank you, Phil Factor! I will be sure to keep the link to NET reflector where I can find it quickly. Now, can you explain those windows? What is wrong with them? Does the author of an article know the code is going to display inside a window less than an inch wide?
_________________
"Look, those sheep have been shorn."
data analyst replies, "On the sides that we can see.."
February 5, 2009 at 6:15 am
katesl (2/5/2009)
Now, can you explain those windows? What is wrong with them? Does the author of an article know the code is going to display inside a window less than an inch wide?
What browser are you using? FireFox is rendering the code blocks correctly on my PC. So it is likely a browser or setting issue. IE 8 also displays them correctly.
Jonathan,
Nice article. Replacement of xp_cmdshell is an excellent reason for using the CLR. Although I have never used xp_cmdshell in any of the database I have worked on.
I would imagine another place to use the CLR would be to replace use of sp_OA... procedures.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
February 5, 2009 at 6:25 am
Browser is IE 6 - Windows 2000 Server SP4 -- this is my machine for maintaining legacy applications.
My standard for application design is NOT to have to step outside to find out why it's displaying that way. If the article is not presented clearly, I can comment on that.
_________________
"Look, those sheep have been shorn."
data analyst replies, "On the sides that we can see.."
February 5, 2009 at 7:13 am
I'd be interested to see if anyone has a solution to the problem of preventing a barf when an invalid path is passed to DirectoryInfo. The obvious idea would be to send a RAISERROR through the Pipe to the SQLExecutionContext via ExecuteAndSend(). The error should be caught by the outer exception handling of the TSQL TRY....CATCH block so you can then do something sensible. However, in SQL Server 2005, the error is thrown back to the CLR and handled as SQLExpection. If the SQLException is caught within the CLR and nothing is done within the CLR CATCH block, then the execution will fail in the T-SQL context with an error, instead of being caught by the TSQL-TRY/CATCH Block. (Jens Suessmeyer in http://connect.microsoft.com/SQLServer/feedback/ViewFeedback.aspx?FeedbackID=251376)
Best wishes,
Phil Factor
February 5, 2009 at 7:33 am
Although SQLCLR has great power I think it is very important to tell the reader that it also brings MANY undesirable things in.
- Bad Exception handling is just one of the examples.
- Bad routines could cause stability problems even knowing that is a "hosted" CLR
- There is a very high risk of introducing code that is not Server-Side friendly.
- Problems caused by CLR objects are a lot harder to deal with.
* Noel
February 5, 2009 at 7:36 am
Last time I worked on a CLR function for SQL Server, I was unable to find a way to handle an exception and pass an error back through the pipe to SQL Server. Now this was a scalar function versus a table value function, but I'm not sure you can handle the error a pass an exception back through the pipe to SQL Server on in a CLR function. You may be stuck with getting the .NET exception back in TSQL. You can do handle the exception and pass an error back through the pipe in a CLR Stored Procedure, however.
February 5, 2009 at 7:37 am
Phil Factor (2/5/2009)
I'd be interested to see if anyone has a solution to the problem of preventing a barf when an invalid path is passed to DirectoryInfo. The obvious idea would be to send a RAISERROR through the Pipe to the SQLExecutionContext via ExecuteAndSend(). The error should be caught by the outer exception handling of the TSQL TRY....CATCH block so you can then do something sensible. However, in SQL Server 2005, the error is thrown back to the CLR and handled as SQLExpection. If the SQLException is caught within the CLR and nothing is done within the CLR CATCH block, then the execution will fail in the T-SQL context with an error, instead of being caught by the TSQL-TRY/CATCH Block. (Jens Suessmeyer in http://connect.microsoft.com/SQLServer/feedback/ViewFeedback.aspx?FeedbackID=251376)
The clean solution is to return null if the existence check fails:
public static IEnumerable os_directory_info(SqlString path, SqlString filter)
{
DirectoryInfo di = new DirectoryInfo(path.Value);
if (di.Exists)
{
if (filter.IsNull || filter.Value == string.Empty)
return di.GetFileSystemInfos();
else
return di.GetFileSystemInfos(filter.Value);
}
else
{
return null;
}
}
Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
My Blog | Twitter | MVP Profile
Training | Consulting | Become a SQLskills Insider
Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]
February 5, 2009 at 7:49 am
noeld (2/5/2009)
Although SQLCLR has great power I think it is very important to tell the reader that it also brings MANY undesirable things in.- Bad Exception handling is just one of the examples.
Actually .NET has very robust exception handling abilities, and if you implement them along with TSQL exception handling there shouldn't be problems.
BEGIN TRY
select *
from dbo.os_directory_info('f:\Start', null)
END TRY
BEGIN CATCH
SELECT error_message()
END CATCH
- Bad routines could cause stability problems even knowing that is a "hosted" CLR
Describe a stability problem that you have encountered in a SAFE/EXTERNAL_ACCESS assembly implementation? If you go UNSAFE all bets are off, but SAFE/EXTERNAL_ACCESS can not cause you stability issues.
- There is a very high risk of introducing code that is not Server-Side friendly.
You also have to run this kind of code with UNSAFE access, so it really is all about how you control what you put into your SQL Server.
- Problems caused by CLR objects are a lot harder to deal with.
Describe a problem caused by a SAFE/EXTERNAL_ACCESS assembly in SQL Server and how it was harder to deal with.
Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
My Blog | Twitter | MVP Profile
Training | Consulting | Become a SQLskills Insider
Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]
Viewing 15 posts - 1 through 15 (of 168 total)
You must be logged in to reply to this topic. Login to reply