Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Table Data Sizes


Table Data Sizes

Author
Message
ngreene
ngreene
SSC Rookie
SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)SSC Rookie (25 reputation)

Group: General Forum Members
Points: 25 Visits: 347
Comments posted to this topic are about the item Table Data Sizes
WILLIAM MITCHELL
WILLIAM MITCHELL
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1734 Visits: 3041

CREATE TABLE #temp
(
[name] nvarchar(128),
[rows] char(11),
[reserved] varchar(18),
[data] varchar(18),
[index_size] varchar(18),
[unused] varchar(18)
)

INSERT INTO #temp
EXEC sp_MSforeachtable @command1="EXEC sp_spaceused '?' "

SELECT
[name] AS TableName,
CAST([rows] AS int) AS NumOfRows,
CAST(REPLACE([reserved],' KB','') AS int) AS [TotalKB]
FROM
#temp
ORDER BY 3 DESC

SELECT SUM(CAST(REPLACE([reserved],' KB','') AS int)) AS TotalKB_data FROM #temp

DROP TABLE #temp


sharath.chalamgari
sharath.chalamgari
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1320 Visits: 798
This code looks much simple than in the article
tskelley
tskelley
Valued Member
Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)Valued Member (63 reputation)

Group: General Forum Members
Points: 63 Visits: 1157
Thanks, William. I was going to post a fix for string sort on reserved, but you caught it.

And thank you ngreene for posting your solution.



SanDroid
SanDroid
UDP Broadcaster
UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)

Group: General Forum Members
Points: 1442 Visits: 1046
Thank you William for posting some code that actually will execute here.
The other code posted in the article would not execute in SQL 2008 R2 SSMS.
TravisDBA
TravisDBA
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1546 Visits: 3069
Way too complicated of a solution for what is needed here. Here the information is in one SELECT statement from three system tables that gives you all the same basic information that sp_spaceused does and without any looping, using TEMP tables, or cursors, and orders then by the largest rows first to boot!. KISS. :-D

SELECT
sysusers.name as TABLE_USER,
sysobjects.name as TABLE_NAME,
sum(sysindexes.rowcnt) as ROWS,
sum(case when sysindexes.indid in (0, 1, 255) then convert(dec(15),reserved*8)else 0 end) as RESERVED_Kb,
sum(case when sysindexes.indid < 2 THEN convert(dec(15),dpages*8) ELSE 0 END) +
sum(case when sysindexes.indid = 255 THEN convert(dec(15),used*8) ELSE 0 END) AS DATA_Kb,
(sum(case when sysindexes.indid in (0, 1, 255) then convert(dec(15),used*8) ELSE 0 END) -
sum(case when sysindexes.indid < 2 THEN convert(dec(15),dpages*8) ELSE 0 END) -
sum(case when sysindexes.indid = 255 THEN convert(dec(15),used*8) ELSE 0 END)) AS INDEX_SIZE_Kb,
sum(case when sysindexes.indid in (0, 1, 255) then convert(dec(15),(reserved - used)*8) else 0 end) AS UNUSED_Kb
FROM sysobjects (NOLOCK) INNER JOIN
sysindexes (NOLOCK) ON sysobjects.id = sysindexes.id
INNER JOIN sysusers (NOLOCK) ON sysobjects.uid = sysusers.uid
WHERE (sysobjects.type = 'U')
group by sysusers.name, sysobjects.name
ORDER BY ROWS DESC
GO

"Technology is a weird thing. It brings you great gifts with one hand, and it stabs you in the back with the other. ...:-D"
SanDroid
SanDroid
UDP Broadcaster
UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)

Group: General Forum Members
Points: 1442 Visits: 1046
WOW!!!
Two good replacement scripts.
However there is great sadness for the readers and users.

Each script returns a differant value in KB for [Reserved].w00t

Travis:
TABLE_USER TABLE_NAME ROWS RESERVED_Kb
dbo TN_AuditLog 257106 455120

William:
TableName NumOfRows TotalKB
TN_AuditLog 128553 732376

Would the real Table size script please stand up?
HINT: The 2008 SSMS UI tells me that TN_AuditLog RowCount = 128553, the Data space is 710 MB

Cool
David Bird
David Bird
Old Hand
Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)

Group: General Forum Members
Points: 315 Visits: 1190
Thanks ngreene for sharing your script. Without it this forum topic and sharing of scripts would not of happened.

SanDroid my visual tests show the results are the same for both scripts except that TravisDBA script does not handle tables with a dbo schema. I do not know why.

WILLIAM MITCHELL script shows all tables but does not display the schema because Microsoft sp_spaceused does not report it.

Last week I finished a similar script that collects row counts and table sizes for all databases in an instance. It is a bit more complicated and still needs more testing to confirm its accuracy. The code is based on other published SQL scripts for which do I give credit to in the comments. It is being tested on SQL Server 2000, 2005, 2008 and 2008 R2. I will be adding it to the SQL Overview Package.

My experience in the past has shown sp_spaceused sizes can be off and the row counts from sysindexes are based on SQL Server optimization statistics that may not always be accurate.

Here is my code


USE [tempdb]
GO
-- Create Temp Table to collect data
IF EXISTS (SELECT *
FROM tempdb.dbo.sysobjects
WHERE id = OBJECT_ID(N'[tempdb].[dbo].[temp_CapturerSpaceUsed]')
)
DROP TABLE [tempdb].[dbo].[temp_CapturerSpaceUsed]
GO

CREATE TABLE [TEMPDB].[dbo].[temp_CapturerSpaceUsed](
[Server] [nvarchar](128) DEFAULT @@SERVERNAME,
[DatabaseName] [nvarchar](128) NULL,
[TableSchema] [nvarchar](50) NOT NULL,
[TableName] [nvarchar](128) NOT NULL,
[Rows_cnt] [nvarchar](32) NOT NULL,
[ReservedKB] [nvarchar](32) NOT NULL,
[DataKB] [nvarchar](32) NOT NULL,
[IndexSzKB] [nvarchar](32) NOT NULL,
[UnusedKB] [nvarchar](32) NOT NULL,
[Package_run_date] [datetime] DEFAULT CURRENT_TIMESTAMP
) ON [PRIMARY]
GO
--------------------------------------------------
-- Create Stored procedure to load data into table

IF OBJECT_ID(N'[dbo].[usp_CapturerSpaceUsed]') IS NOT NULL
DROP PROCEDURE [dbo].[usp_CapturerSpaceUsed];
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO


CREATE PROCEDURE [usp_CapturerSpaceUsed]
@DatabaseName NVARCHAR(128)
AS
BEGIN
SET NOCOUNT ON;
---------------------------------------------------------------------------
---------------------------------------------------------------------------
-- Posts used as a references in creating this stored procedure
-- http://www.novicksoftware.com/Articles/sql-server-table-space-reporting-sp_spaceused.htm
-- http://www.sqlservercentral.com/scripts/Miscellaneous/30317/

DECLARE @TableSchema NVARCHAR(50)
DECLARE @TableName NVARCHAR(600)
DECLARE @SQL NVARCHAR(2000)

DECLARE @I AS INT
DECLARE @Row_Count AS INT
SET @I = 1

-- Get list of tabes in database \\
IF OBJECT_ID('tempdb..#TableList') IS NOT NULL DROP TABLE #TableList
CREATE TABLE #TableList (ID_num int IDENTITY(1,1),TableSchema NVARCHAR (50),TableName NVARCHAR (128) )
INSERT INTO #TableList (TableSchema,TableName) EXEC ('SELECT TABLE_SCHEMA, TABLE_NAME FROM [' + @DatabaseName + '].INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = ''BASE TABLE'' ORDER BY 1,2;')

-- Create table to capture resulst from sp_spaceused
IF OBJECT_ID('tempdb..#sp_spaceused') IS NOT NULL DROP TABLE #sp_spaceused
CREATE TABLE #sp_spaceused (TableName NVARCHAR (128) ,[Rows_cnt] [nvarchar](32),[ReservedKB] [nvarchar](32),[DataKB] [nvarchar](32),[IndexSzKB] [nvarchar](32),[UnusedKB] [nvarchar](32))

SET @Row_Count = (SELECT COUNT(*) FROM #TableList)

-- Cursorless loop
WHILE @I <= @Row_Count
BEGIN

-- The replace is used to handle table names with apostophes
SELECT @TableSchema = TableSchema, @TableName = REPLACE(TableName,'''','''''')
FROM #TableList WHERE ID_Num = @I;
-- Get sp_spaceused data
SET @SQL = '[' + @DatabaseName + ']..sp_spaceused @objname=''[' + @TableSchema + '].[' + @TableName + ']''';
-- SELECT @SQL
DELETE FROM #sp_spaceused ;
INSERT INTO #sp_spaceused EXEC (@SQL);
-- Save sp_spaceused data with server, database, and table schema
INSERT INTO [tempdb].[dbo].[temp_CapturerSpaceUsed]
([Server]
,[DatabaseName]
,[TableSchema]
,[TableName]
,[Rows_cnt]
,[ReservedKB]
,[DataKB]
,[IndexSzKB]
,[UnusedKB]
,[Package_run_date])
SELECT @@SERVERNAME, @DatabaseName, @TableSchema, TableName
,[Rows_cnt],[ReservedKB],[DataKB],[IndexSzKB],[UnusedKB], current_timestamp
FROM #sp_spaceused;

SET @I = @I + 1
END
DROP TABLE #TableList
DROP TABLE #sp_spaceused

END
GO
--------------------------------------------------
-- Process each database
SET NOCOUNT ON
DECLARE @DBName NVARCHAR(128)

DECLARE db_cursor CURSOR FOR
SELECT name
FROM master.dbo.sysdatabases
WHERE name <> 'TEMPDB'
AND CONVERT(nvarchar(128),DATABASEPROPERTYEX(name,'Status')) = 'ONLINE'
ORDER BY name

OPEN db_cursor
FETCH NEXT FROM db_cursor
INTO @DBName

WHILE @@FETCH_STATUS = 0
BEGIN
EXEC [usp_CapturerSpaceUsed] @DatabaseName = @DBName

FETCH NEXT FROM db_cursor
INTO @DBName
END
CLOSE db_cursor
DEALLOCATE db_cursor
GO
--------------------------------------------------
-- Cleanup
USE tempdb
GO
IF OBJECT_ID(N'[dbo].[usp_CapturerSpaceUsed]') IS NOT NULL
DROP PROCEDURE [dbo].[usp_CapturerSpaceUsed];
GO

SELECT [Server]
,[DatabaseName]
,[TableSchema]
,[TableName]
,CAST ([Rows_cnt] AS decimal(18, 0)) AS [Rows_cnt]
,CAST (REPLACE([ReservedKB], ' KB','') AS decimal(18, 0)) AS [ReservedKB]
,CAST (REPLACE([DataKB], ' KB','') AS decimal(18, 0)) AS [DataKB]
,CAST (REPLACE([IndexSzKB], ' KB','') AS decimal(18, 0)) AS [IndexSzKB]
,CAST (REPLACE([UnusedKB], ' KB','') AS decimal(18, 0)) AS [UnusedKB]
,[Package_run_date]
FROM [tempdb].[dbo].[temp_CapturerSpaceUsed]

ORDER BY [Rows_cnt] DESC



David Bird

My PC Quick Reference Guide
SanDroid
SanDroid
UDP Broadcaster
UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)

Group: General Forum Members
Points: 1442 Visits: 1046
David Bird (12/8/2010)

SanDroid my visual tests show the results are the same for both scripts except that TravisDBA script does not handle tables with a dbo schema. I do not know why.

Neither do I since all the tables I tested it against have only a DBO schema and the ROW count was off by 12 million rows on the first table.
Could it be that his script was counting table rows and table index rows?

BTW: I tested your script and it is scary. It took forever to complete, and does not sort correctly on the Rows_cnt or ReservedKB columns. Perhaps storing an Int as an Int would be more efficient?

In the 9GB OLTP live database I tested it against; Williams solution was the only one that found the largest table in the DB and listed it as the first row of the select. I tried ordering by Rows and TotalKB (ReservedKB).
David Bird
David Bird
Old Hand
Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)

Group: General Forum Members
Points: 315 Visits: 1190
SanDroid,

You are right about the order. The columns types where still character because that is how sp_spaceused returnsthem. I updated the code with a a select that converts them to numbers without the trailing "KB" text, the order is set for row counts.

To get the total space used by a table you have to add the 4 KB columns together and order by the result. At least that is my theory.

Its does run longer than I would like for the 6,000+ tables in the instance I test with.

David Bird

My PC Quick Reference Guide
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search