Need Minimally Logged Operation to Cause Checkpoint!

  • I am preparing for a presentation next week and am digging for an example....

    I need a minimally logged operation that will show the behavior that a checkpoint is ran when a minimally logged operation occurs while in SIMPLE or BULK_LOGGED recovery model.

    I have tried rebuilding, creating and dropping indexes...I have created heaps using SELECT..INTO, but nothing seems to consistently generate a CHECKPOINT.

    What am I doing wrong?

    Here is where I read that they should cause checkpoints:

    us/library/ms189573(v=sql.105).aspx

    Here is the list I am using for minimally logged operations:

    http://msdn.microsoft.com/en-us/library/ms191244(v=sql.105).aspx

    I am using the following to look for checkpoints:

    select * from fn_dblog(null,null) WHERE Operation IN ('LOP_BEGIN_CKPT','LOP_END_CKPT')

    Any help would be greatly appreciated!

  • you can explicitly call CHECKPOINT yourself, would that help?

    --UPDATE MyTABLE ....

    --INSERT INTO SomeTable

    CHECKPOINT

    --UPDATE MyTABLE2 ....

    --INSERT INTO SomeTable2

    CHECKPOINT

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • I would have some doubts about that BoL page, never seen a minimally logged operation trigger a checkpoint before and besides, it doesn't need to trigger a checkpoint. Any data modification that is minimally logged has to be written to the data file before the transaction completes, that's done by the thread that executes the minimally logged operation (called an eager write), so there would be no reason for a checkpoint afterwards.

    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
  • Just got back from a little walk and that is what I was thinking Gail (not the smart stuff, but that BoL is probably under stating the conditions)...

    Oh well...

    I will remove it from my presentation 🙂

    Thanks for all the help!

    -Dane

  • If you're doing a presentation on bulk-logged, maybe there's something in here for you?

    http://www.sqlservercentral.com/articles/Recovery+Model/89664/

    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
  • Thanks Gail 🙂

    I had found that on my hunt for more information...I am actually doing a presentation on the T-LOG...

    Per Sean McCown, I purposefully selected a rough topic that would require a ton of research...typically when I present I would always pick something that I could naturally talk about for hours.

    I am trying to learn enough so that I can pass the cert tests (w/o boot camps).

    Thanks again!

    -Dane

  • dkschill (4/5/2013)


    Thanks Gail 🙂

    I had found that on my hunt for more information...I am actually doing a presentation on the T-LOG...

    You've seen the stairway article series on that topic?

    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
  • Found those as well 🙂

    Using those to validate and flush out my points.

    This presentation is going to be brutal for the listeners if I don't clean it up some this weekend...lots of content...

    Any other references you could throw out would be much appreciated!

    Thanks again for the help!

    -Dane

  • GilaMonster (4/5/2013)

    Any data modification that is minimally logged has to be written to the data file before the transaction completes

    I don't think that's true. If it is, it violates the write-ahead-logging model, which SQL Server uses; only log records should have to be hardened for a transaction to complete, not data blocks.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • ScottPletcher (4/5/2013)


    GilaMonster (4/5/2013)

    Any data modification that is minimally logged has to be written to the data file before the transaction completes

    I don't think that's true. If it is, it violates the write-ahead-logging model, which SQL Server uses; only log records should have to be hardened for a transaction to complete, not data blocks.

    I'll go with Gail on this one having reread this article: http://www.sqlservercentral.com/articles/Recovery+Model/89664/.

  • ScottPletcher (4/5/2013)


    GilaMonster (4/5/2013)

    Any data modification that is minimally logged has to be written to the data file before the transaction completes

    I don't think that's true. If it is, it violates the write-ahead-logging model, which SQL Server uses; only log records should have to be hardened for a transaction to complete, not data blocks.

    It does not violate write-ahead logging. Write-ahead logging requires that the log records are written to disk before the data pages that they represent, it does not say anything about the timing between the data pages being written and the end of the transaction. In both minimally and fully logged operations, the log records are hardened on disk before the data pages are written back to the data file.

    The difference in terms of writing is that in a fully logged operation, the data changes can be written at any point after the log records, before or after the transaction is committed, because the log records fully describe the changes and hence the change can be redone from just the log records.

    In a minimally logged operation, the data changes are written to disk after the log records and before the transaction is considered committed because the log records do not fully describe the change, there's only enough logging for undo operations (the very definition of minimally logged) and hence redo is not possible. As such, the changes must be hardened to disk before the commit is complete to ensure durability.

    You can see why if you consider the potential scenario of a crash the millisecond after a bulk operation has committed. If the data changes were not required to be written to disk prior to the commit of the transaction then such a crash could leave a minimally logged operation with the log records describing the change hardened in the log file but the changes data pages not on disk. Since the definition of minimally logged is 'enough logging for undo, not for redo', in such a case SQL would not be able to replay that bulk operation as part of crash recovery and would be required to mark that database as suspect (inconsistent). This obviously is not an acceptable option.

    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

Viewing 11 posts - 1 through 10 (of 10 total)

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