Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Table Data Sizes Expand / Collapse
Author
Message
Posted Wednesday, December 8, 2010 2:47 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 2:03 PM
Points: 1,334, Visits: 3,069
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.

"Technology is a weird thing. It brings you great gifts with one hand, and it stabs you in the back with the other. ..."
Post #1032181
Posted Wednesday, December 8, 2010 3:56 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 2:03 PM
Points: 1,334, Visits: 3,069
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.

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. ..."
Post #1032213
Posted Thursday, December 9, 2010 6:48 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, October 21, 2014 1:55 PM
Points: 185, Visits: 1,022
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
Post #1032431
Posted Thursday, December 9, 2010 7:50 AM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 2:03 PM
Points: 1,334, Visits: 3,069
Yes,you can do that or just comment that clause out and you will see more...

"Technology is a weird thing. It brings you great gifts with one hand, and it stabs you in the back with the other. ..."
Post #1032465
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse