December 8, 2010 at 12:09 am
Comments posted to this topic are about the item Table Data Sizes
December 8, 2010 at 5:45 am
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
December 8, 2010 at 6:04 am
This code looks much simple than in the article
December 8, 2010 at 7:03 am
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.
December 8, 2010 at 9:45 am
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.
December 8, 2010 at 11:00 am
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. 😀
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"
December 8, 2010 at 11:17 am
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_USERTABLE_NAMEROWSRESERVED_Kb
dbo TN_AuditLog257106455120
William:
TableNameNumOfRowsTotalKB
TN_AuditLog128553 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
😎
December 8, 2010 at 12:39 pm
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[/url].
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
December 8, 2010 at 2:15 pm
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).
December 8, 2010 at 2:44 pm
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
December 8, 2010 at 2:47 pm
Please do remember that sysindexes.rowcnt is only as correct as your latest indexes and stats are up to date. If you have not done this in a while then that column will not be correct.:-D
"Technology is a weird thing. It brings you great gifts with one hand, and it stabs you in the back with the other. ...:-D"
December 8, 2010 at 3:56 pm
After conversing with SanDroid, I have amended this query slightly so that the schema name and indid is displayed as well. Not all of you may need to see all of this detail. If so, just filter it out. Notice the sysusers join doesn't always match up sometimes.:-D
SELECT
sys.schemas.name as [Schema Name],
sysusers.name as TABLE_USER,
sysobjects.name as TABLE_NAME,
sysindexes.rowcnt as ROWS,
sysindexes.indid as [Index],
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
LEFT JOIN sysusers (NOLOCK) ON sysobjects.uid = sysusers.uid
LEFT JOIN sys.schemas (NOLOCK) ON sysobjects.UID = sys.schemas.schema_id
WHERE (sysobjects.type = 'U')
AND (sysindexes.indid = 1)
group by sys.schemas.name,sysusers.name, sysobjects.name,sysindexes.rowcnt,sysindexes.indid
ORDER BY ROWS DESC, [SCHEMA NAME],TABLE_NAME
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"
December 9, 2010 at 6:48 am
TravisDBA,
I notice some tables where still being skipped after your latest changes. The query excludes tables without a clustered index.
To include them, modify the where clause to use (sysindexes.indid <= 1) .
The Adventureworks database has a few tables that use HEAP instead of a clustered index. This makes it a good database to test the query against.
David Bird
December 9, 2010 at 7:50 am
Yes,you can do that or just comment that clause out and you will see more...:-D
"Technology is a weird thing. It brings you great gifts with one hand, and it stabs you in the back with the other. ...:-D"
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply