After applying some Windows updates to one of my servers, I started getting the following error when I ran a customer .NET SQL-CLR stored proc:
Server: Msg 6522, Level 16, State 2, Line 1
A .NET Framework error occurred during execution of user defined routine or aggregate ‘somemethodyourecalling’:System.IO.FileLoadException: Could not load file or assembly ‘System.Drawing, Version=2.0.0.0, Culture=neutral, PublicKeyToken=b03f5f7f11d50a3a’ or one of its dependencies. Assembly in host store has a different signature than assembly in GAC. (Exception from HRESULT: 0x80131050)
I’d imported some additional assemblies into SQL Server for use in SQL CLR mapped stored procedures, and the Windows updates had included a service pack for .NET, which changed some of the assemblies. Now the version I’d linked to SQL Server no longer existed on disk, and SQL couldn’t load it – that made sense, and is documented pretty clearly in this MS Support article: http://support.microsoft.com/kb/949080
However, I had dozens of servers with SQL CLR components enabled, and hundreds of different assemblies loaded across them all, and not always the same in each server, so a standard update script wouldn’t work to refresh all the changed assemblies (the MS Support link provides a list of the standard ones that cause that error, but if you’ve got custom assemblies loaded, or you’ve loaded an assembly that’s not specifically cleared for SQL CLR, then it’s not on the list either). To deal with this, I wrote a script that fetches the assembly list for a database and attempts to refresh every one of them from their disk location. If they haven’t changed, the update attempt will fail with a specific error message about the MVID, and there’s no change for that assembly.
Also, I’ve commented out the line that restricts it to just framework assemblies (System.* and Microsoft.*), but you can uncomment that line if you’d like to restrict the refresh from attempting to reload your custom assemblies as well.
DECLARE @AssemblyName VARCHAR(255), @AssemblyLocation VARCHAR(255), @AlterAssemblyCommand NVARCHAR(1024), @DotNetFolder VARCHAR(100) SET @DotNetFolder = 'C:\Windows\Microsoft.NET\Framework\v2.0.50727' CREATE TABLE #Results ( AssemblyName VARCHAR(255), AssemblyLocation VARCHAR(255), AlterAssemblyCommand NVARCHAR(1024), Results VARCHAR(1024) ) select sa.name as AssemblyName, saf.name as Assemblylocation, case when charindex('', saf.name) = 0 then 'ALTER ASSEMBLY [' + sa.name + '] FROM ''' + @DotNetFolder else 'ALTER ASSEMBLY [' + sa.name + '] FROM ''' end + saf.name + (case right(saf.name, 4) when '.dll' then '' else '.dll' end) + '''' as AlterAssemblyCommand INTO #Refresh from sys.assemblies sa join sys.assembly_files saf on sa.assembly_id = saf.assembly_id where sa.name <> ('Microsoft.SqlServer.Types') --and (sa.name like 'System.%' or sa.name like 'microsoft.%') DECLARE Commands CURSOR FAST_FORWARD FOR SELECT AssemblyName, AssemblyLocation, AlterAssemblyCommand FROM #Refresh OPEN Commands FETCH NEXT FROM Commands INTO @AssemblyName, @AssemblyLocation, @AlterAssemblyCommand WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY exec sp_executesql @AlterAssemblyCommand insert into #Results SELECT @AssemblyName, @AssemblyLocation, @AlterAssemblyCommand, 'Assembly refreshed successfully' END TRY BEGIN CATCH insert into #Results SELECT @AssemblyName, @AssemblyLocation, @AlterAssemblyCommand, CASE ERROR_NUMBER() WHEN 6285 THEN 'No update necessary (MVID match)' WHEN 6501 THEN 'Physical assembly not found at specified location (SQL Error 6501)' ELSE ERROR_MESSAGE() + ' (SQL Error ' + convert(varchar(10), ERROR_NUMBER()) + ')' END END CATCH FETCH NEXT FROM Commands INTO @AssemblyName, @AssemblyLocation, @AlterAssemblyCommand END CLOSE Commands DEALLOCATE Commands SELECT * FROM #Results drop table #refresh drop table #Results
While troubleshooting the error, I came across this as well – I don’t have a SQL 2012 server handy to check with, it looks like this problem might be resolved with a reboot in SQL 2012:
http://msdn.microsoft.com/en-us/library/hh479773.aspx
I’m not sure if that’s the case, but it would make things easier. Also, it would be nice if there was some kind of “ALTER ASSEMBLY [SomeAssembly] REFRESH” command to address this problem, but maybe in a future version.
Additionally, this error can be caused if the signing of an assembly has changed, but not necessarily the signature, but just reloading it from disk won’t work because the method that SQL Server uses to determine if there’s been a change is the MVID, and that doesn’t change unless there’s been a code change of some kind (see the Connect bug here). In those cases, you’ll actually need to drop and recreate the assembly, including any supporting objects that rely on that assembly.