Hell yeah Solomon, that helped indeed!!
And as we say in Holland; "you do your name proud", i'm definitely going to try to manually load System.Management.dll into the assembly, because that one that contains all the mountpoint info i need. The unsafe status is not an issue here, because the DB it's being used in is my own SqlManagement DB, so i'm the only user of it.
As for the suggestion of 'single treadedness', i can confirm that. If i run 2 console apps at the same time they both take much longer to complete.
When i cut down all my console apps / processes accessing Win32_Volume to just ONE at a time, i got much better runtimes.
That being said, i still have at random interval much longer runtimes. Which is probably my (single) console app or process interfering with SCOM which is probable also trying to use the same system.management.dll.
Knowing this, i'm rebuilding my stored proc that is called by all sorts of code in my management tool on demand, to a process that runs once a minute that updates a table using Win32_Volume that all other processes can access at will, thus cutting down the chances of hitting a busy Win32_Volume thread
And if for some reason the System.Management.dll in my CLR project does not work, your other suggestion of just calling the 6 KB console app from xp_cmdshell, is the next best thing. I think padded columns is the easiest: just a 7 substrings per returned row.
Somthing like this:
Select
cast(substring(outputstring, 1,25) as bigint) as var1,
cast(substring(outputstring,26,25) as bigint) as var2,
..etc..
from xpCmdShellOutput
Once i've tested all of the above options and the chosen one it is stable on my most challenging prod environment (3 way stretched cluster with 7 instances per node with 139 mountpoints) i will post my source code here for anyone else struggeling with this scale / stability problem.
Thanks again Solomon, and if we ever do meet in the flesh, i will most definitely buy you a drink
Theo Ekelmans (2/27/2015)
Hell yeah Solomon, that helped indeed!!And as we say in Holland; "you do your name proud", i'm definitely going to try to manually load System.Management.dll into the assembly, because that one that contains all the mountpoint info i need. The unsafe status is not an issue here, because the DB it's being used in is my own SqlManagement DB, so i'm the only user of it.
As for the suggestion of 'single treadedness', i can confirm that. If i run 2 console apps at the same time they both take much longer to complete.
When i cut down all my console apps / processes accessing Win32_Volume to just ONE at a time, i got much better runtimes.
Thanks :-). But honestly, I was only speaking in terms of SQL Server's CLR host / SQLCLR in terms of thread-safety issues. There is a single App Domain used for all sessions / SPIDs accessing a particular Assemby in SQL Server so static, class-level variables are shared among them. Console apps and Windows apps use a separate App Domain per each instance of those apps so static, class-level variables are not shared across users / processes / instances of the app. So, I was just warning that IF your code could be called by more than one Session at a time, that could certainly be prone to error, though not guaranteed to be a problem (hence the additional testing needed).
Again, the main concern for loading System.Management.dll is, even if it loads now, Microsoft can change it to a mixed (MSIL and C++) assembly, making it unloadable into SQL Server, which means you would have to scrap this particular SQLCLR code. Of course, that day may never come, but it is a risk to factor into any decision making process.
Regarding the xp_cmdshell idea: I generally use SQLCLR as a means of avoiding xp_cmdshell, but in this particular case it does remove that risk of System.Management.dll potentially not working in the future.
Also, while doing 7 substrings should work every time, there is always a chance of something going wrong with text parsing. Using XML as the format at least removes one point of failure from the process. Slightly bulkier, but a lot more reliable / less brittle.
Thanks again Solomon, and if we ever do meet in the flesh, i will most definitely buy you a drink
No problem. Glad I could help and I appreciate the offer :-D.
Take care, solomon...
SQL# — https://SQLsharp.com/ ( SQLCLR library ofover 340 Functions and Procedures)
Sql Quantum Lift — https://SqlQuantumLift.com/ ( company )
Sql Quantum Leap — https://SqlQuantumLeap.com/ ( blog )
Info sites — Collations • Module Signing • SQLCLR
Theo, I just found something that might help.
Is it safe to say that you are only checking mount points where you currently have data and/or log files? These are the ones that you need to know if they are running out of space, right? As opposed to ALL mount points?
If just the ones that have DB files on them, check out the sys.dm_os_volume_stats DMV (introduced in SQL Server 2008 R2).
You can try the following query (assuming you are using SQL Server 2008 R2 or newer):
SELECT files.*, '---' AS [---], stat.*
FROM sys.[master_files] files
CROSS APPLY sys.dm_os_volume_stats(files.[database_id], files.[file_id]) stat;
SQL# — https://SQLsharp.com/ ( SQLCLR library ofover 340 Functions and Procedures)
Sql Quantum Lift — https://SqlQuantumLift.com/ ( company )
Sql Quantum Leap — https://SqlQuantumLeap.com/ ( blog )
Info sites — Collations • Module Signing • SQLCLR
Hi Solomon,
Again... you do you name justice
Considering that i'm usually only interested in drives that belong to the instance the query is actually running on, this query will do for the mountpoints that actually hold DB files.
SELECT distinct volume_mount_point, logical_volume_name, total_bytes, available_bytes
FROM sys.[master_files] files
CROSS APPLY sys.dm_os_volume_stats(files.[database_id], files.[file_id]) stat
order by volume_mount_point
Worst case workaround, is to place a dummy DB on the drives/mountpoints that have no normal database... <shivers>, which is a nasty workaround that i would rather like to avoid
.....<pondering>..... But considering that at this moment i do not have mountpoints that do not contains databases, i will rebuild my stored proc to optionally use this method.
But in the mean time (and for SQL 2008 R2 and up), i will use this script to join the sys.dm with xp_fixeddrives for a reasonably complete list of all drives in a server instance.
/**************************************************************************************
Free and total bytes per drive / mountpoint
***************************************************************************************
BEWARE: only mountpoints are shown that have active database files on them
***************************************************************************************
Versie: 1.0
Autheur: Theo Ekelmans / Solomon Rutzky
Datum: 2015-04-14
***************************************************************************************
enable OLA if needed
***************************************************************************************
exec sp_configure 'show advanced options', 1
reconfigure
exec sp_configure 'Ole Automation Procedures', 1
reconfigure
***************************************************************************************/
SET NOCOUNT ON
DECLARE @hr int
DECLARE @fso int
DECLARE @drive char(1)
DECLARE @odrive int
DECLARE @TotalSize varchar(20)
DECLARE @MB bigint ; SET @MB = 1048576
CREATE TABLE #drives (drive char(1) PRIMARY KEY,
FreeSpace bigint NULL,
TotalSize bigint NULL)
--Get the "normal drives"
INSERT #drives(drive,FreeSpace)
EXEC master.dbo.xp_fixeddrives
UPDATE #drives
SET FreeSpace=FreeSpace * @MB
-- update the list with the total size
EXEC @hr=sp_OACreate 'Scripting.FileSystemObject',@fso OUT
IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso
DECLARE dcur CURSOR LOCAL FAST_FORWARD
FOR SELECT drive from #drives
ORDER by drive
OPEN dcur
FETCH NEXT FROM dcur INTO @drive
WHILE @@FETCH_STATUS=0
BEGIN
EXEC @hr = sp_OAMethod @fso,'GetDrive', @odrive OUT, @drive
IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso
EXEC @hr = sp_OAGetProperty @odrive,'TotalSize', @TotalSize OUT
IF @hr <> 0 EXEC sp_OAGetErrorInfo @odrive
UPDATE #drives
SET TotalSize=@TotalSize
WHERE drive=@drive
FETCH NEXT FROM dcur INTO @drive
END
CLOSE dcur
DEALLOCATE dcur
EXEC @hr=sp_OADestroy @fso
IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso
-- Put the output in temp table
SELECTcast(drive + ':\' as varchar(128)) as [drive]
,cast('' as varchar(128)) as [VolumeName]
,FreeSpace as [Free]
,TotalSize as [Total]
into#out
FROM#drives
DROP TABLE #drives
--Merge the results with sys.dm_os_volume_stats
update#out
setVolumeName = mp.VolumeName
,Free = mp.Free
,Total = mp.Total
from#out inner join (SELECT distinct volume_mount_point as [drive], logical_volume_name as [VolumeName], available_bytes as [Free], total_bytes as [Total]
FROM sys.[master_files] files
CROSS APPLY sys.dm_os_volume_stats(files.[database_id], files.[file_id]) stat) as mp
on #out.drive = mp.drive
insertinto #out
SELECTdistinct volume_mount_point as [drive], logical_volume_name as [VolumeName], available_bytes as [Free], total_bytes as [Total]
FROMsys.[master_files] files
CROSS APPLY sys.dm_os_volume_stats(files.[database_id], files.[file_id]) stat
wherevolume_mount_point not in (select [drive] FROM#out)
--Show combined results
select *
from #out
--Cleanup
drop table #out
Thanks again
Viewing 8 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply