How to retrieve size information for all the tables in a SQL Server Database

How to retrieve size information for all the tables in a SQL Server Database

Share on Facebook0Share on Google+0Tweet about this on TwitterShare on LinkedIn0Share on Reddit0
In an older post, I described how you could rebuild all the indexes of a database in SQL Server by making use of the undocumented stored procedure “sp_MSforeachtable”.

Another common task is when you want to retrieve size information for all the tables in a database.

Again, by using “sp_MSforeachtable“, you can easily do that in three simple steps:

–Step 1:
–Create temporaty table for the session
create table #tblInfo(
[name] nvarchar (255),
rows int,
reserved varchar(100),
data varchar(100),
index_size varchar(100),
unused varchar(100)
);


–Step 2:
–Using the stored procedure sp_spaceused retrieve
–the size information for all tables and store it in the temporary table
EXEC sp_MSforeachtable @command1=”INSERT #tblInfo EXEC sp_spaceused ‘?'”;


–Step 3:
–Access the results
select * from #tblInfo;

Note: Because sp_spaceused returns the size information as a string (except the number of rows), you will have to manipulate the data in the temporary table using casting prior to run sorting operations etc.

Examples:

–Sort the results by unused space (descending)
select * from #tblInfo
order by cast(substring(unused,0,charindex(‘ ‘,unused)) as int) desc;


–Sort the results by reserved space (descending)
select * from #tblInfo
order by cast(substring(reserved,0,charindex(‘ ‘,reserved)) as int) desc;

Additionally, you can create another temporary table which can contain the converted values (i.e. in MB instead of KB) of the first table.

For examnple:

select [name],
rows,
cast(substring(reserved,0,charindex(‘ ‘,reserved)) as int)/1024 as reserved_in_MB,
cast(substring(data,0,charindex(‘ ‘,data)) as int)/1024 as data_in_MB,
cast(substring(index_size,0,charindex(‘ ‘,index_size)) as int)/1024 as index_size_in_MB,
cast(substring(unused,0,charindex(‘ ‘,unused)) as int)/1024 as unused_in_MB
into #tblInfoConverted
from #tblInfo;


–and … voila!
select *
from #tblInfoConverted
order by reserved_in_MB desc;


Until next time!


Recommended eBooks on SQL Server:

Tuning SQL Server: eBook by SQL Server MVP Artemakis Artemiou
Tuning SQL Server: eBook by SQL Server MVP Artemakis Artemiou
Administering SQL Server: eBook by SQL Server MVP Artemakis Artemiou
Administering SQL Server: eBook by SQL Server MVP Artemakis Artemiou
Artemakis Artemiou
Artemakis Artemiou is a Senior SQL Server Architect, Author, Software Developer and a Microsoft Data Platform MVP. He has over 15 years of experience in the IT industry in various roles. Among other, via his initiative SQLEBooks.com, Artemakis authors and publishes eBooks on different topics on SQL Server. Artemakis currently serves as the President of the Cyprus .NET User Group (CDNUG) and the International .NET Association Country Leader for Cyprus (INETA). Additionally he is the founder of the SQLArtBits initiative that aims to provide the technical community with simple, yet powerful and high-quality SQL Server tools. Currently, the highlights of these tools are DBA Security Advisor and In-Memory OLTP Simulator. Artemakis's official website can be found at aartemiou.com. Artemakis's blogs can be found at: SQLNetHub.com and TechHowTos.com.