If we ever remove a variable length column (varchar) or TEXT column from one of our table, a certain amount of wasted space will be there in that table's physical representation. We can reclaim this space with the DBCC CLEANTABLE statement. Let us see how to use DBCC CLEANTABLE with a sample code snippet
Sample table structure
CREATE TABLE TableWithText
(
[FirstName] [char] (50),
[Age] [int] NULL,
[Resume] [text]
)
GO
Insert sample data into the table.
Insert into TableWithText Values ('Vadivel',28,'AAAAAAAAAAAA')
Insert into TableWithText Values ('Sailakshmi',27,'BBBBBBBBBBB')
Insert into TableWithText Values ('Vadi',58,'CCCCCCCCCCCCCCC')
To check the size of the table
sp_MStablespace TableWithText
Now let us drop the column ("Resume") with Text datatype
Alter table TableWithText drop column Resume
Try to check the size of the table again
sp_MStablespace TableWithText
There wouldn't be any change in the size of the table. Actually as we have removed a column of TEXT datatype we need to expect the size of the table to reduce down considerably. For that execute the below sql statement
DBCC CLEANTABLE ('pubs','TableWithText') -- parameters are database name and the table name
Drop the fixed length ("FirstName") column now
Alter table TableWithText Drop Column FirstName
Now if you check the size of the table there won't be any change at all. Thats because we reclaim the space only if we remove TEXT or variable length fields from our table.
DBCC Cleantable has an optional third parameter where we can specify the batch size. i.e., the number of rows which would be processed per transaction. If not specified, the statement processes the entire table in one transaction this might sometime throw timeout error.
DBCC CLEANTABLE ('pubs','TableWithText', 2)
Related Links:
1. Reclaiming a table space after dropping a column [With Clustered Index] - http://vadivel.blogspot.com/2007/10/reclaiming-table-space-after-dropping.html
2. Reclaiming the table space after dropping a column [Without Clustered Index] - http://vadivel.blogspot.com/2007/10/reclaiming-table-space-after-dropping_01.html
Sample table structure
CREATE TABLE TableWithText
(
[FirstName] [char] (50),
[Age] [int] NULL,
[Resume] [text]
)
GO
Insert sample data into the table.
Insert into TableWithText Values ('Vadivel',28,'AAAAAAAAAAAA')
Insert into TableWithText Values ('Sailakshmi',27,'BBBBBBBBBBB')
Insert into TableWithText Values ('Vadi',58,'CCCCCCCCCCCCCCC')
To check the size of the table
sp_MStablespace TableWithText
Now let us drop the column ("Resume") with Text datatype
Alter table TableWithText drop column Resume
Try to check the size of the table again
sp_MStablespace TableWithText
There wouldn't be any change in the size of the table. Actually as we have removed a column of TEXT datatype we need to expect the size of the table to reduce down considerably. For that execute the below sql statement
DBCC CLEANTABLE ('pubs','TableWithText') -- parameters are database name and the table name
Drop the fixed length ("FirstName") column now
Alter table TableWithText Drop Column FirstName
Now if you check the size of the table there won't be any change at all. Thats because we reclaim the space only if we remove TEXT or variable length fields from our table.
DBCC Cleantable has an optional third parameter where we can specify the batch size. i.e., the number of rows which would be processed per transaction. If not specified, the statement processes the entire table in one transaction this might sometime throw timeout error.
DBCC CLEANTABLE ('pubs','TableWithText', 2)
Related Links:
1. Reclaiming a table space after dropping a column [With Clustered Index] - http://vadivel.blogspot.com/2007/10/reclaiming-table-space-after-dropping.html
2. Reclaiming the table space after dropping a column [Without Clustered Index] - http://vadivel.blogspot.com/2007/10/reclaiming-table-space-after-dropping_01.html
Comments
If there's a clustered index on the table you can use DBCC DBREINDEX on it. If not, then a clustered index can be created and then dropped - it also should do the trick as both of these methods trigger table rebuild. Unfortunately both only work in SQL2005+. If you have an SQL2000 you'll have to recreate the table manually.