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


Who Truncated That Table & What Do I Do Now?


Who Truncated That Table & What Do I Do Now?

Author
Message
Divine Flame
Divine Flame
SSCarpal Tunnel
SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)SSCarpal Tunnel (4.4K reputation)

Group: General Forum Members
Points: 4383 Visits: 2816
Comments posted to this topic are about the item Who Truncated That Table & What Do I Do Now?


Sujeet Singh
Koen Verbeeck
Koen Verbeeck
SSC Guru
SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)SSC Guru (61K reputation)

Group: General Forum Members
Points: 61983 Visits: 13297
Interesting and detailed article, thanks.


How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?
My blog at SQLKover.

MCSE Business Intelligence - Microsoft Data Platform MVP
INCREDIBLEmouse
INCREDIBLEmouse
SSC-Enthusiastic
SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)SSC-Enthusiastic (192 reputation)

Group: General Forum Members
Points: 192 Visits: 241
I see the "myth" is busted for Full model.
Is it still un-busted for the other models?
steve.bailey 29413
steve.bailey 29413
Grasshopper
Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)Grasshopper (11 reputation)

Group: General Forum Members
Points: 11 Visits: 36
TRUNCATE TABLE isn't a fully logged operation but as Sujeet's findings show it is logged in the transaction log (It's always logged regardless of recovery model - I'd be very concerned if it wasn't) so you can roll it back provided that you haven't committed the transaction that included the TRUNCATE TABLE statement. This doesn't mean that it logs all the rows in the table in the transaction log like the DELETE statement (if it did it wouldn't be as immediate as it is). If you do commit the transaction, the only way to recover the contents of the table is to perform a point in time restore from backup (just like Sujeet indicated). If you are using the simple model, it will still be logged and can be rolled back, you just won't be able to perform a point in time restoration of the database (unless that point in time happens to be when you performed a full backup of the database).

According to Kalen Delaney it doesn't quite fit into the minimally logged category either...
http://sqlblog.com/blogs/kalen_delaney/archive/2010/10/12/tsql-tuesday-11-rolling-back-truncate-table.aspx
TheSQLGuru
TheSQLGuru
SSC-Dedicated
SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)

Group: General Forum Members
Points: 31997 Visits: 8671
I recommend using ApexSQL's transaction log centric tools. Pretty amazing what they can do as far as redo/undo from tlog activity!! They don't have any competitor that I know of in that space. The first time you can unwind a "HOLY SH!T" event where you update all rows in a table or some such you will be very happy you have the product(s).

Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
Robert Davis
Robert Davis
SSCertifiable
SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)

Group: General Forum Members
Points: 6568 Visits: 1632
Are they going to create newer versions of their log tool? I read that it won't be updated for SQL 2012 or 2014 because MSFT is no longer giving anyone access to their log format.



My blog: SQL Soldier
Twitter: @SQLSoldier
My book: Pro SQL Server 2008 Mirroring
Microsoft Certified Master, SQL Server MVP
Database Engineer at BlueMountain Capital Management
erwin oosterhoorn
erwin oosterhoorn
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: 1075 Visits: 404
To make sure that you can find the time of truncation you have to adjust the query a bit, as you can't find the time if another action has been performed to the table.
Changing it to:

SET NOCOUNT ON;
DECLARE @ObjectName SYSNAME

SET @ObjectName = 'dbo.TestTable'
-- Your schema qualified table name here

--============== Retrieving the UserName & Time when the table was truncated, based on the TransactionID

SELECT @ObjectName AS ObjectName
, [Transaction Name]
, SUSER_SNAME([Transaction SID]) AS UserName
, [Begin Time]
, Operation
, [Transaction ID]
FROM fn_dblog(NULL, NULL)
WHERE [Transaction ID] IN (SELECT [Transaction ID]
FROM fn_dblog(NULL, NULL)
WHERE AllocUnitName = @ObjectName)
AND [Transaction Name] LIKE 'TRUNCATE%'
AND Operation = 'LOP_BEGIN_XACT'


allows you to find the truncation, might have to have an order by if there are more than one in the lifetime of the log.
SQLRNNR
SQLRNNR
SSC Guru
SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)

Group: General Forum Members
Points: 66147 Visits: 18570
INCREDIBLEmouse (6/5/2014)
I see the "myth" is busted for Full model.
Is it still un-busted for the other models?


Truncate is still a logged operation in the other models.

The myth has been long busted around this one.



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

SQLRNNR
SQLRNNR
SSC Guru
SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)SSC Guru (66K reputation)

Group: General Forum Members
Points: 66147 Visits: 18570
steve.bailey 29413 (6/5/2014)
TRUNCATE TABLE isn't a fully logged operation but as Sujeet's findings show it is logged in the transaction log (It's always logged regardless of recovery model - I'd be very concerned if it wasn't) so you can roll it back provided that you haven't committed the transaction that included the TRUNCATE TABLE statement. This doesn't mean that it logs all the rows in the table in the transaction log like the DELETE statement (if it did it wouldn't be as immediate as it is). If you do commit the transaction, the only way to recover the contents of the table is to perform a point in time restore from backup (just like Sujeet indicated). If you are using the simple model, it will still be logged and can be rolled back, you just won't be able to perform a point in time restoration of the database (unless that point in time happens to be when you performed a full backup of the database).

According to Kalen Delaney it doesn't quite fit into the minimally logged category either...
http://sqlblog.com/blogs/kalen_delaney/archive/2010/10/12/tsql-tuesday-11-rolling-back-truncate-table.aspx


Way to fill in the gaps.

Glad you discussed the "fully" logged issue too. Cool



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

Robert Davis
Robert Davis
SSCertifiable
SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)

Group: General Forum Members
Points: 6568 Visits: 1632
Technically, truncate is a fully logged operation. It deallocates pages and those are logged. Every action it performs is logged. The confusion is that record deletions are not logged, but it doesn't perform record deletions. It performs deallocations.



My blog: SQL Soldier
Twitter: @SQLSoldier
My book: Pro SQL Server 2008 Mirroring
Microsoft Certified Master, SQL Server MVP
Database Engineer at BlueMountain Capital Management
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