SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


spaceused of a table


spaceused of a table

Author
Message
gugan_ta
gugan_ta
SSC-Enthusiastic
SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)SSC-Enthusiastic (126 reputation)

Group: General Forum Members
Points: 126 Visits: 541
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
ps.
ps.
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3229 Visits: 3668
is your post incomplete? what is the query?



Pradeep Singh
Elliott Whitlow
Elliott Whitlow
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10012 Visits: 5314
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
Bill Talada
Bill Talada
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1139 Visits: 1992
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.
Jesse Reich
Jesse Reich
SSC Veteran
SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)SSC Veteran (274 reputation)

Group: General Forum Members
Points: 274 Visits: 1022
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
*/


Bill Talada
Bill Talada
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1139 Visits: 1992
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.
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