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»»

Truncate Table Partition command Expand / Collapse
Author
Message
Posted Thursday, February 4, 2010 5:41 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Sunday, May 11, 2014 8:07 PM
Points: 891, Visits: 235
Comments posted to this topic are about the item Truncate Table Partition command


Post #860065
Posted Thursday, February 18, 2010 1:03 PM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, October 2, 2013 9:39 AM
Points: 329, Visits: 195
I dont know if i am wrong but is there a easy way out for this.

May be if i say.

Partition function fx(10,20,30)
partition scheme sc on fx all to primary
Create Table blabla_bla ( i int primary Key scheme fx(i))on fx(i)

create table blabla_bla_mirror( i int primary Key scheme fx(i))on fx(i))

switch partiton x to blabla_bla_mirror (x)

your partition is empty now

drop table mirror.


Regards
Vinay
Post #868453
Posted Saturday, February 20, 2010 10:27 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Sunday, May 11, 2014 8:07 PM
Points: 891, Visits: 235
Hi Vinay,

Yes,
For truncating partition you need to create the mirror/dummy table with similar schema and on same file group where the partition is residing; and then use the Alter tables switch statement.

Dont you think that considerable manual work is involved here?
This procedure automates the all the steps involved. You dont need to know about schema of the table, file group of the partition etc, you do not need to create and drop the dummy tables etc.

Also if you are migrating some code/database from Oracle to SQL Server where ALTER TABLE ..TRUNCATE PARTITION command is used, you can replace such statement by adding call to this procedure here.

Regards,
Vidhyadhar



Post #869677
Posted Saturday, February 20, 2010 10:29 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Sunday, May 11, 2014 8:07 PM
Points: 891, Visits: 235
One more thing is this procedure takes care if the partition is compressed. One more manual step is eliminated.
If you are doing it manually you need to find out compression type of Partition and Mirror/Dummy table should have same Compression.

Regards,
Vidhaydhar



Post #869679
Posted Wednesday, March 17, 2010 3:41 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, August 8, 2012 1:11 AM
Points: 1, Visits: 29
Hello,

if i have a table containing an auto increment unique id, this table is partitioned based on date time field.

what happens to the auto increment values when i truncate a partition?

Will the partitions that are still available inherit the truncated id's or will the id continue incrementing as if nothing happened?

Post #884485
Posted Wednesday, March 17, 2010 9:05 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Sunday, May 11, 2014 8:07 PM
Points: 891, Visits: 235
Yes second option is correct. it will keep on incrementing from the last IDENTITY value.


Post #884772
Posted Tuesday, June 29, 2010 6:05 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, September 16, 2010 3:49 AM
Points: 1, Visits: 15
I found a little bug in the code. I tested some of the code for clustered indexes together with other indexes and it failed because when looking for the columns of
the clustered indexes it also added those for the non-clustered indexes. The red part I added to solve this problem.

COLUMN_NAME=
(SELECT name FROM sys.columns E WHERE E.OBJECT_ID=B.object_id AND E.column_id=D.column_id),
D.is_descending_key,
C.is_unique
FROM SYS.OBJECTS B
INNER JOIN sys.INDEXES C ON
B.object_id=C.object_id
INNER JOIN sys.index_columns D ON
B.object_id=D.object_id AND D.index_id=1
WHERE B.TYPE='U'
AND (C.index_id=1)
AND B.object_id=@TAB_ID1
Post #944559
Posted Thursday, October 28, 2010 4:20 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, May 5, 2011 7:20 AM
Points: 1, Visits: 40
Vijay,

This is a gem. Nice work. I dont usually feel compelled to comment on forums but this saved me a lot of work and gave me an elegant solution, so well done.

A couple of comments.

I found that when dealing with a partition that had been row compressed the script did not create a row compressed empty table. This was because my partitions did not have an index = 1. Removal of this clause and everything ran smoothly.

Secondly, the name of this article is slightly misleading (apologies for the literalness). The script does not truncate a partition, it removes it, as the switched out partition is never switched back in. To truncate a partition, you need to switch out, truncate then switch back in.

For me the most beneficial aspects of this script is the ability to create an empty replica of an existing table through T-SQL.

Well done.
Paul.
Post #1012182
Posted Wednesday, November 3, 2010 11:06 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 10:39 AM
Points: 3, Visits: 237
Very clever script, Vidya! Nice work.

The only problem I encountered during testing was that the target table clustered indexes would sometimes get created with their columns in the wrong order. This would cause the SWITCH command to fail and return the error:

Msg 4947, Level 16, State 1, Line 1
ALTER TABLE SWITCH statement failed. There is no identical index in source table '<db_name>.<schema>.<src_tbl_name>' for the index '<idx_name>' in target table '<db_name>.<schema>.<trgt_tbl_name>' .


The solution to this problem was a simple addition of ORDER BY ordinal position on the index columns at the end of this section:


INSERT INTO @pkInfo
(SCHEMANAME, table_name,pk_name,columnName,asckey,IsUnique)
SELECT
SCHEMANAME=@SchemaName,
B.NAME TABLE_NAME,
PK_NAME=
(SELECT a.name PK_NAME FROM sys.indexes a
WHERE A.OBJECT_ID=B.OBJECT_ID AND A.index_id=1),
COLUMN_NAME=
(SELECT name FROM sys.columns E WHERE E.OBJECT_ID=B.object_id AND E.column_id=D.column_id),
D.is_descending_key,
C.is_unique
FROM SYS.OBJECTS B
INNER JOIN sys.INDEXES C ON
B.object_id=C.object_id
INNER JOIN sys.index_columns D ON
B.object_id=D.object_id AND D.index_id=1
WHERE B.TYPE='U'
AND (C.index_id=1)
AND B.object_id=@TAB_ID1
ORDER BY D.key_ordinal
Post #1015435
Posted Friday, November 5, 2010 8:13 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Sunday, May 11, 2014 8:07 PM
Points: 891, Visits: 235
Thanks for your testing and feedback. Now a days im busy and not able to accomodate the feedback. Sorry for that.


Post #1016846
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse