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


Truncate Table Partition command


Truncate Table Partition command

Author
Message
vidya_pande
vidya_pande
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: 1099 Visits: 242
Comments posted to this topic are about the item Truncate Table Partition command



bhushanvinay
bhushanvinay
Old Hand
Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)Old Hand (397 reputation)

Group: General Forum Members
Points: 397 Visits: 196
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
vidya_pande
vidya_pande
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: 1099 Visits: 242
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



vidya_pande
vidya_pande
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: 1099 Visits: 242
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



joewazen
joewazen
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 31
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?
vidya_pande
vidya_pande
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: 1099 Visits: 242
Yes second option is correct. it will keep on incrementing from the last IDENTITY value.



maurice_peek
maurice_peek
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 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
Paul.Gamblen-594531
Paul.Gamblen-594531
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 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.
jfoster-540652
jfoster-540652
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 272
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
vidya_pande
vidya_pande
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: 1099 Visits: 242
Thanks for your testing and feedback. Now a days im busy and not able to accomodate the feedback. Sorry for that.



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