Execute the following Microsoft SQL Server T-SQL script to create a table-valued function and a stored procedure to list all drives with total disk space and free disk space. Note that the table-valued function "join"-ed with a CROSS APPLY in the sproc to obtain the final results.
USE AdventureWorks2008;
GO
/*
-- Turn on OLE automation if not on
exec sp_configure 'show advanced options', 1
go
RECONFIGURE
GO
exec sp_configure 'Ole Automation Procedures', 1
GO
RECONFIGURE
GO
*/
CREATE FUNCTION fnTotalDriveSpace
(@DriveLetter CHAR(1))
RETURNS @Total TABLE (MaxSpaceGB money)
BEGIN
DECLARE @return INT, @fso INT, @GetDrive VARCHAR(16)
DECLARE @drv INT, @DriveSizeinBytes VARCHAR(32)
SET @GetDrive = 'GetDrive("' + @DriveLetter + '")'
EXEC @return = sp_OACreate 'Scripting.FileSystemObject', @fso OUTPUT
SET @DriveSizeinBytes = NULL
IF @return = 0
EXEC @return = sp_OAMethod @fso, @GetDrive, @drv OUTPUT
IF @return = 0
EXEC @return = sp_OAGetProperty @drv,'TotalSize', @DriveSizeinBytes OUTPUT
EXEC sp_OADestroy @drv
EXEC sp_OADestroy @fso
INSERT @Total values (
(((convert(bigint,@DriveSizeinBytes)/ 1024)/ 1024)/1024) )
RETURN
END
GO
-- select * from dbo.fnTotalDriveSpace('C')
CREATE PROC sprocDriveSpaceInfo
AS
BEGIN
DECLARE @Drives TABLE ( DriveLetter char(1), FreeGB money)
INSERT @Drives (DriveLetter, FreeGB)
EXEC xp_fixeddrives
UPDATE @Drives SET FreeGB = Floor(FreeGB/1024)
SELECT
DriveLetter,
FreeGB=convert(int,FreeGB),
MaxSpaceGB=convert(int,MaxSpaceGB)
FROM @Drives d
CROSS APPLY dbo.fnTotalDriveSpace (d.DriveLetter)
ORDER BY DriveLetter
END
GO
EXEC sprocDriveSpaceInfo
GO
Results:
DriveLetter | FreeGB | MaxSpaceGB |
C | 316 | 688 |
D | 1 | 9 |
No comments:
Post a Comment