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


Table Data Sizes


Table Data Sizes

Author
Message
TravisDBA
TravisDBA
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1462 Visits: 3069
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"
TravisDBA
TravisDBA
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1462 Visits: 3069
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"
David Bird
David Bird
SSC Veteran
SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)SSC Veteran (271 reputation)

Group: General Forum Members
Points: 271 Visits: 1186
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

My PC Quick Reference Guide
TravisDBA
TravisDBA
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1462 Visits: 3069
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"
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