January 24, 2013 at 2:50 am
Hi all experts,
I am a newbie.I am trying to write a query which would give me the server wise level of the space unused by all the database. For doing this task i search in google and found out
EXECUTE master.sys.sp_MSforeachdb 'USE [?]; EXEC sp_spaceused'
Which work like a gem. I tried to get the output of the above query in an temp table as
CREATE TABLE #EXECPLAN(database_name NVARCHAR(1000),database_size nvarchar(100),unallocated_space nvarchar(100),reserved nvarchar(100),data nvarchar(100),index_size nvarchar(100),unused nvarchar(100))
INSERT INTO #EXECPLAN
EXECUTE master.sys.sp_MSforeachdb 'USE [?]; EXEC sp_spaceused'
SELECT * FROM #EXECPLAN
The above query is not working because sp_spaceused returns 2 select statement am i am not able to figure it out how , i can insert the output of this 2 select statement in a temp table
January 24, 2013 at 2:53 am
DECLARE @sql NVARCHAR(MAX)
SELECT @sql =
REPLACE(
CAST(
(
SELECT 'USE ' + QUOTENAME(name) +';' + CHAR(13) + CHAR(10) +
--PUT WHAT YOU WANT TO DO IN EACH DATABASE IN THIS BLOCK
----
'SELECT ' + CHAR(13) + CHAR(10) +
'DatabaseName = DB_NAME(), ' + CHAR(13) + CHAR(10) +
'a.FILEID, ' + CHAR(13) + CHAR(10) +
'[FILE_SIZE_MB] = CONVERT(DECIMAL(12, 2), ROUND(a.size / 128.000, 2)), ' + CHAR(13) + CHAR(10) +
'[SPACE_USED_MB] = CONVERT(DECIMAL(12, 2), ROUND(fileproperty(a.NAME, ' + CHAR(39) + 'SpaceUsed' + CHAR(39) +') / 128.000, 2)), ' + CHAR(13) + CHAR(10) +
'[FREE_SPACE_MB] = CONVERT(DECIMAL(12, 2), ROUND((a.size - fileproperty(a.NAME, ' + CHAR(39) + 'SpaceUsed' + CHAR(39) +')) / 128.000, 2)), ' + CHAR(13) + CHAR(10) +
'a.NAME, a.FILENAME ' + CHAR(13) + CHAR(10) +
'FROM dbo.sysfiles a;' + CHAR(13) + CHAR(10)
----
FROM
sys.databases
FOR XML PATH('')
) AS NVARCHAR(MAX)
),
'&#x 0D;',CHAR(13) + CHAR(10) --REMOVE THE SPACE ON THIS LINE BEFORE RUNNING
)
--SELECT @sql
EXECUTE sp_executesql @sql
Remove the space between x and 0 in the string in the code '&#x 0D;'
This will loop through the databases, getting file size, used space, free space for each DB file.
January 24, 2013 at 3:24 am
Thanks antony. Looping through database is what i was looking for . Once again thanks.
January 24, 2013 at 3:33 am
Antony,
Is there any easy way to traverse throught all the database. Because i am finding the above query a little bit of difficcult to understand.
January 24, 2013 at 3:36 am
query sys.master_files, there is a size column which is in pages, so multiply the value by 8, to get size in KB for that file, then sum them up based on the database.
Wont get you used space or free space, but will get total space
January 24, 2013 at 3:53 am
Shadab Shah (1/24/2013)
Antony,Is there any easy way to traverse throught all the database. Because i am finding the above query a little bit of difficcult to understand.
Might be this is what you are looking for:
IF OBJECT_ID ('tempdb..##DatabaseFileDetails') IS NOT NULL
BEGIN
DROP TABLE ##DatabaseFileDetails;
END
GO
EXECUTE sp_msforeachdb N'USE [?]
IF OBJECT_ID (''tempdb..##DatabaseFileDetails'') IS NULL
BEGIN
SELECTDB_NAME() AS DatabaseName,
[file_id] AS FileId,
[name] AS [FileName],
[type_desc] AS FileType,
[state_desc] AS FileState,
CAST(((*8/1024.0)/1024.0) AS DECIMAL(18,2)) AS FileSizeGB,
CAST((((FILEPROPERTY([name],''spaceused'')*8)/1024.0)/1024.0) AS DECIMAL(18,2)) AS UsedSpaceGB,
CAST(((((size - FILEPROPERTY([name],''spaceused''))*8)/1024.0)/1024.0) AS DECIMAL(18,2)) AS FreeSpaceGB,
-- AS PagesAllocated,
--FILEPROPERTY([name],''spaceused'') AS UsedPages,
--(size)- (FILEPROPERTY([name],''spaceused'')) AS FreePages,
[physical_name] AS FilePath
INTO##DatabaseFileDetails
FROMsys.database_files
END
ELSE
INSERT INTO ##DatabaseFileDetails
SELECTDB_NAME() AS DatabaseName,
[file_id] AS FileId,
[name] AS [FileName],
[type_desc] AS FileType,
[state_desc] AS FileState,
CAST(((*8/1024.0)/1024.0) AS DECIMAL(18,2)) AS FileSizeGB,
CAST((((FILEPROPERTY([name],''spaceused'')*8)/1024.0)/1024.0) AS DECIMAL(18,2)) AS UsedSpaceGB,
CAST(((((size - FILEPROPERTY([name],''spaceused''))*8)/1024.0)/1024.0) AS DECIMAL(18,2)) AS FreeSpaceGB,
-- AS PagesAllocated,
--FILEPROPERTY([name],''spaceused'') AS UsedPages,
--(size)- (FILEPROPERTY([name],''spaceused'')) AS FreePages,
[physical_name] AS FilePath
FROMsys.database_files'
GO
SELECT*
FROM##DatabaseFileDetails
ORDER BY DatabaseName
The query is almost same as Anthony's. The only difference is that I am using sp_msforeachdb to loop through the databases & I am calculating the space in GB instead of MB.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply