Benefits of DBCC Check DB and performance

  • I have some confusion here with DBCC , as i know that DBCC will take a snapshot of the DB to perform a Check DB. Am i correct? If yes, then is there any benefit in using a snapshot in DBCC and how will DBCC perform a check DB on system DBs... Can any one please clarify me....

    Thanks in advance !!!!

  • Yes, the DBCC CHECKDB will create a (hidden) snapshot from the database. Because this is a clompletely automated process, you are not in control about the placement of the files. This could cause free space issues on disk if you have large full disk and a heavily used database.

    You can create a snapshot manually and perform the CHECKDB against this manually created snapshot. This gives you the benefit of keeping in control of the (snapshot)files. You could put these files on a seperate disk. This way the CHECKDB will have less performance impact on the disks with the original databasefiles.

    ** Don't mistake the ‘stupidity of the crowd’ for the ‘wisdom of the group’! **
  • But, by snapshotting to a seperate set of disks and then performing DBCC there, you won't be seeing the physical layout checks run against the original set of disks. If you go down this road, you'll still need to run DBCC PHYSICAL_ONLY to validate the original database files and their storage.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (8/20/2013)


    But, by snapshotting to a seperate set of disks and then performing DBCC there, you won't be seeing the physical layout checks run against the original set of disks.

    Doesn't that only apply to the changed data pages? The original version of all these changed data pages are stored in the snapshot file(s). All non-changed data pages are read from the database location.

    ** Don't mistake the ‘stupidity of the crowd’ for the ‘wisdom of the group’! **
  • HanShi (8/20/2013)


    Grant Fritchey (8/20/2013)


    But, by snapshotting to a seperate set of disks and then performing DBCC there, you won't be seeing the physical layout checks run against the original set of disks.

    Doesn't that only apply to the changed data pages? The original version of all these changed data pages are stored in the snapshot file(s). All non-changed data pages are read from the database location.

    Even if it's only the changed data pages, then those are not getting checked. I'm fine with offloading logical checks to another server (backup & restore), but doing this just ensures that some parts of the system are not checked. Not an approach I can get excited about.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (8/20/2013)


    But, by snapshotting to a seperate set of disks and then performing DBCC there, you won't be seeing the physical layout checks run against the original set of disks.

    Yes you are. The snapshot is just to get a transactionally-consistent view of the data. The only pages in the snapshot are ones that are changing at the time that CheckDB is running, if the source for those were damaged, you'd be getting massive errors during the copy-on-write process and the concurrent access anyway.

    Saying that a snapshot means that the original data doesn't get checked means that the hidden snapshot is also not acceptable (it's on the same logical drive, not necessarily the same physical disk, definitely not the same spot on the disk), so you're advocating CheckDB with table locks as the only 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
  • HanShi (8/19/2013)


    This way the CHECKDB will have less performance impact on the disks with the original databasefiles.

    Exceedingly unlikely, unless you happen to be running CheckDB at a time when large portions of the database are changing (which is a bad idea usually)

    CheckDB's IO impact comes from reading every single allocated page in the database, not from writing to the snapshot.

    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
  • GilaMonster (8/20/2013)


    Grant Fritchey (8/20/2013)


    But, by snapshotting to a seperate set of disks and then performing DBCC there, you won't be seeing the physical layout checks run against the original set of disks.

    Yes you are. The snapshot is just to get a transactionally-consistent view of the data. The only pages in the snapshot are ones that are changing at the time that CheckDB is running, if the source for those were damaged, you'd be getting massive errors during the copy-on-write process and the concurrent access anyway.

    Saying that a snapshot means that the original data doesn't get checked means that the hidden snapshot is also not acceptable (it's on the same logical drive, not necessarily the same physical disk, definitely not the same spot on the disk), so you're advocating CheckDB with table locks as the only acceptable option.

    I thought the internal/hidden snapshot was a different critter than the snapshots we create. But, hey, happy to be wrong.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • I think the internal snapshot for dbcc is the same process as a "database snapshot" using a sparse file in NTFS, but you don't have control over the placement of where it is.

    From the OP, I'm not sure what the question means. When you run dbcc, you don't get to choose to use a snapshot or not. It uses a snapshot internally, but it also hits the existing database. A "database snapshot" you have created doesn't really change the way dbcc works.

  • Grant Fritchey (8/20/2013)


    I thought the internal/hidden snapshot was a different critter than the snapshots we create. But, hey, happy to be wrong.

    No, the same thing, same behaviour, same mechanics.

    The only difference with the CheckDB snapshot is that it's created on all editions (only on Enterprise can you create an explicit snapshot) and it puts the snapshot files into NTFS alternate streams.

    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
  • GilaMonster (8/20/2013)


    Grant Fritchey (8/20/2013)


    I thought the internal/hidden snapshot was a different critter than the snapshots we create. But, hey, happy to be wrong.

    No, the same thing, same behaviour, same mechanics.

    The only difference with the CheckDB snapshot is that it's created on all editions (only on Enterprise can you create an explicit snapshot) and it puts the snapshot files into NTFS alternate streams.

    But if you run DBCC against a snapshot, do you get another snapshot? And since it's going back to the original pages anyway for all the reads, what's the point of separating it out?

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (8/20/2013)


    GilaMonster (8/20/2013)


    Grant Fritchey (8/20/2013)


    I thought the internal/hidden snapshot was a different critter than the snapshots we create. But, hey, happy to be wrong.

    No, the same thing, same behaviour, same mechanics.

    The only difference with the CheckDB snapshot is that it's created on all editions (only on Enterprise can you create an explicit snapshot) and it puts the snapshot files into NTFS alternate streams.

    But if you run DBCC against a snapshot, do you get another snapshot?

    No.

    And since it's going back to the original pages anyway for all the reads, what's the point of separating it out?

    Transactional consistency for logical checks. Otherwise you'd have to do it the SQL 2000 way, of running crash recovery in-memory to get a stable view of the tables. Massively complex. Snapshots ensure transactional consistency and a stable view of the tables which means that the CheckDB process doesn't have to worry about concurrent changes while working through the database.

    That's why the alternative to using a snapshot is WITH TABLOCK - take table level locks to ensure the table can't change while being checked.

    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
  • GilaMonster (8/20/2013)


    Grant Fritchey (8/20/2013)


    GilaMonster (8/20/2013)


    Grant Fritchey (8/20/2013)


    I thought the internal/hidden snapshot was a different critter than the snapshots we create. But, hey, happy to be wrong.

    No, the same thing, same behaviour, same mechanics.

    The only difference with the CheckDB snapshot is that it's created on all editions (only on Enterprise can you create an explicit snapshot) and it puts the snapshot files into NTFS alternate streams.

    But if you run DBCC against a snapshot, do you get another snapshot?

    No.

    And since it's going back to the original pages anyway for all the reads, what's the point of separating it out?

    Transactional consistency for logical checks. Otherwise you'd have to do it the SQL 2000 way, of running crash recovery in-memory to get a stable view of the tables. Massively complex. Snapshots ensure transactional consistency and a stable view of the tables which means that the CheckDB process doesn't have to worry about concurrent changes while working through the database.

    That's why the alternative to using a snapshot is WITH TABLOCK - take table level locks to ensure the table can't change while being checked.

    Sorry, you misunderstood the second part of that question. Not why does Microsoft create a snapshot when doing DBCC. I've read Paul's explanation there. I meant, why would you create your own snapshot first?

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Grant Fritchey (8/20/2013)


    I meant, why would you create your own snapshot first?

    I wouldn't.

    Only reason maybe is if the drive with the data files on is nearly full and there's enough concurrent activity that the snapshot runs the drive out of space. But in that case there are other problems that need to be fixed.

    Other case, when there's some filter driver or other installed software that breaks NTFS alternate streams. In that case CheckDB will fail, so you can try and run CheckDB on an explicitly created snapshot to see if the problem is just the alternate streams and as a way to run until the offending software gets fixed or removed.

    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 for understanding to get the Checkdb implementations with the snapshots.

Viewing 15 posts - 1 through 15 (of 17 total)

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