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

spaceused of a table Expand / Collapse
Author
Message
Posted Thursday, September 17, 2009 7:35 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Tuesday, March 18, 2014 5:06 AM
Points: 56, Visits: 504
Hi,

Pls find my query

used sp_spaceused to find the size of a table1 and the result is

Table Name : table1
Rows : 12212058
reserved : 8829816 KB
data : 8828192 KB
Index size : 56 KB
unused : 1568KB

But when i copy the same table1 into Table1_copy it is showing different size

Table Name : table1_copy
Rows : 12212058
reserved : 2175448 KB
data : 2175392 KB
Index size : 16 KB
unused : 40 KB

Pls help which one is correct also if table1_copy is correct...then guide how to get correct space from table1

Note :
NO index has been created in table1 and also tried @updateusage in sp_spaceused.. but it showing
the same result

Thnaks...Gugan


Post #789632
Posted Thursday, September 17, 2009 7:39 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Sunday, July 6, 2014 3:07 PM
Points: 2,242, Visits: 3,643
is your post incomplete? what is the query?




Pradeep Singh
Post #789637
Posted Thursday, September 17, 2009 8:25 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, May 15, 2014 5:11 PM
Points: 6,067, Visits: 5,283
I"m thinking you had a highly fragmented table that has never had an index rebuild. Does this table have a Primary Key and/or Clustered Index (usually the same one), if so it has an index. If not, then why not. When you copied the data it was copied with all the data compacted and only taking the space necessary to house it. The first table appears to have been subjected to extensive page splitting..

You need to periodically reindex your tables and update stats. The optimization jobs will help with parts of that. 8GB is big but not that big for a table..

CEWII
Post #789677
Posted Monday, June 11, 2012 11:56 AM


SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Today @ 5:41 AM
Points: 128, Visits: 820
I'm having the same problem on a table with a varbinary(max) column. I have 21 rows at 2 MB in the varbinary(max) column totaling about 44 MB for the table but sp_spaceused shows 310 MB used. Even update statistics or reindexing doesn't change that number. If I copy the data to a new table, it will show 44 MB for the new table. In other words, I don't think reindexing is moving the off page data nor calculating its true size.

Post #1313981
Posted Thursday, June 14, 2012 1:29 AM
SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Tuesday, June 17, 2014 9:54 AM
Points: 164, Visits: 954
Is it possible the table had a column dropped? Or an update to a previously wide column that made it smaller?

You can duplicate the problem this way:

USE tempdb
GO

IF EXISTS (SELECT * FROM sys.tables WHERE name = 'SizeCheck') DROP TABLE SizeCheck
GO

IF EXISTS (SELECT * FROM sys.tables WHERE name = 'SizeCheck2') DROP TABLE SizeCheck2
GO

CREATE TABLE SizeCheck (
ID INT NOT NULL IDENTITY(1,1) PRIMARY KEY,
Value VARCHAR(8000)
)

INSERT SizeCheck (Value)
SELECT SPACE(8000)
FROM sys.all_objects

UPDATE SizeCheck SET Value = SPACE(1)

SELECT * INTO SizeCheck2 FROM SizeCheck

EXEC sp_spaceused SizeCheck
EXEC sp_spaceused SizeCheck2

/*
name rows reserved data index size unused
SizeCheck 1987 16008 KB 15896 KB 72 KB 40 KB
SizeCheck2 1987 80 KB 48 KB 8 KB 24 KB
*/

Post #1315656
Posted Thursday, June 14, 2012 1:09 PM


SSC-Enthusiastic

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

Group: General Forum Members
Last Login: Today @ 5:41 AM
Points: 128, Visits: 820
You got it right! I have a varbinary(max) that holds 25MB and gets updated down to 2MB but even reindexing the clustered index does not recover the space of off page data. Every row wastes 23MB of unused space that is treated as not available. I'm using ss2005.
Post #1316142
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse