TECHNICAL QUESTION on TRUNCATING and DELETING

  • TECHNICAL QUESTION

    TRUE/FALSE

    1.) When a table is TRUNCATED the TR-LOG is updated.

    2.) When a table is DROPPED the TR-LOG is updated.

    I'd say #2 is TRUE but I am not sure about #1

  • Every change is logged in the transaction logged. That allows point-in-time restores and rollbacks.

    CREATE TABLE rollbacktest( id int);

    INSERT INTO rollbacktest

    SELECT database_id FROM sys.databases;

    BEGIN TRAN;

    TRUNCATE TABLE rollbacktest;

    DROP TABLE rollbacktest;

    ROLLBACK TRAN;

    SELECT * FROM rollbacktest;

    DROP TABLE rollbacktest;

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • There is no such thing as an unlogged operation in SQL. Every change to data, objects or the database itself is logged.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • mw112009 (1/28/2016)


    TECHNICAL QUESTION

    TRUE/FALSE

    1.) When a table is TRUNCATED the TR-LOG is updated.

    2.) When a table is DROPPED the TR-LOG is updated.

    I'd say #2 is TRUE but I am not sure about #1

    Luis and Gail are exactly correct. TRUNCATE deallocates pages rather than deleting data and that deallocation is what's fully logged. It's why you can actually do a rollback on a TRUNCATE if it's in an explicit transaction.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • If you are bored/Interested like I am then you can use fn_dblog to check the actual operation. I was playing with this and could see:

    LOP_BEGIN_XACTLCX_NULL0000:00000cbcNULLTRUNCATE TABLE

    .

    .

    .

    .

    .LOP_BEGIN_XACTLCX_NULL0000:00000cbdNULLDeferredAllocUnitDrop::Process

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply