DBCC CHECKDB - how use it in a maintenance plan ?

  • hello,

    do you think it necessary to use DBCC CHECKDB ? how use it in sql server agent ? before backup ?

    thanks to answer.

    Yann.

    French Geek.
    http://blog.developpez.com/ylarvor
    I work my english 🙂

  • Sure it's necessary. CheckDB checks to see if there's any corruption of any form in the database. Invalid checksums, bad page linkage, out of range column values, etc

    I would suggest you run it before the backup, and maybe not backup the DB is there's corruption. A backup of a corrupt database is not very useful

    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
  • I would always run this regularly. If you can run it before every backup, do that and page out errors. As mentioned, if there are problems, then your backup might be worthless.

    At least run it weekly

  • I certainly reccommend running CHECKDB, but I think it should be run at the most convenient time of the day which may not be when you do a backup.

    At my old place the optimum time for backup was before the overnight batch work started, which put the backups under time pressure to complete. After the bulk of the batch work had finished at about 4AM, we had another window where we ran CHECKDB.

    I understand the issues of checking if your DB is good before doing a backup, but if we did find corruption there was always a good backup we could go back to and transaction log backups to bring us up to the point of failure if not the curent point in time. On good disk systems it is very unlikely you will get a corrupted database, so you need to balance the risks of doing or not doing a CHECKDB before a backup.

    Back in the 1990s I worked on mainframe DB2. There were good vendor backup utilities that included the equivalent of a CHECKDB in the backup processing. Because the I-O needed to check if the database was OK was combined with the I-O needed to run the backup, doing the DB check in-line with the bacukp only added about 5% to backup completion time. It would be great if one of the backup vendors for SQL Server could do this type of thing, it would be a major selling point!

    Original author: https://github.com/SQL-FineBuild/Common/wiki/ 1-click install and best practice configuration of SQL Server 2019, 2017 2016, 2014, 2012, 2008 R2, 2008 and 2005.

    When I give food to the poor they call me a saint. When I ask why they are poor they call me a communist - Archbishop Hélder Câmara

  • I have another question about checkdb. I just started at a new employer and am wondering about a nightly job that I found. Here's the only thing in it:

    dbcc checkdb (dbname) with no_infomsgs.

    If you run the checkdb command without any repair arguments, does it actually DO anything to the database? Is it correct to say that without a repair argument, it's only going to provide information?

    What benefit would there be from running this with no_infomsgs on a nightly basis? And if even if I left off that argument, what benefit would there be to running it as nightly job? Does it write the checkdb results to the log?

  • Marcia Q (10/16/2008)


    If you run the checkdb command without any repair arguments, does it actually DO anything to the database? Is it correct to say that without a repair argument, it's only going to provide information?

    Indeed. It checks for corruption and will write results into the error log.

    CheckDB shouldn't be run with any of the repair options. They are there as a last resort if the corruption can't be fixed by rebuilding indexes or by restoring a clean backup.

    What benefit would there be from running this with no_infomsgs on a nightly basis? And if even if I left off that argument, what benefit would there be to running it as nightly job? Does it write the checkdb results to the log?

    With that option, it just reports on corruption. Without that, it will give you a list of tables that it's checked and the number of rows/pages each has. Personally I find that a waste of space and unnecessary. There are easier ways to see the rowcount/pagecount of a table.

    Nightly may be a little more often than you need. I usually suggest once a week. If you have the time overnight, there's no harm in running it though.

    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
  • Into maintenance plan put "Check database integrity task". this will run DBCC Checkdb.

  • I run the integrity check nightly using the PHYSICAL_ONLY option, and weekly perform a full integrity check.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • Thanks, everyone! At my last place, we included the integrity checks in the maint plan. I'm not sure why they don't do that here.

    Next question... Do you know how I can go about deliberately corrupting a database. I'd like to test some different things, but I'm not sure how to go about it.

  • Hi Gila,

    According from 'dbcc checkdb (dbname) with no_infomsgs.' , you said run

    that command before backup run. But my questions is, what do we do if I already setup a job like

    21:00 - dbcc checkdb (dbname) with no_infomsgs

    22:00 - DBCC BackupDB(DBname)

    23:00 - DBCC RebuildIndex

    1. How do we know database is corrupt before the Backup at 22:00? Job is already setup and backup the corrupt database anyway according from the JOB. Any way to stop that, NOT to backup?

    2. Which command can fix and repair the Database if 'dbcc checkdb' result is failed.

    3. Do you have any sample code to check database, run the db repair if needed then backup and rebuild DB?

    Thanks.

  • Here you go:

    http://blogs.msdn.com/sqlserverstorageengine/archive/2007/03/22/easy-way-to-create-a-corrupt-database-for-testing.aspx

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

  • Do you know how I can go about deliberately corrupting a database. I'd like to test some different things, but I'm not sure how to go about it.

    Sure. First though, a disclaimer for anyone else who wants to try this. Do not do this to a DB you care about. Do not do this to a database that you're not willing to discard. Do not ever consider doing it to a production database.

    Stop SQL. Open the mdf file in a hex editor. Go at least 800kb into the database (to avoid corrupting the system tables) and then randomly change values. Save the file and exit, then restart SQL

    Or, if you're feeling adventurous, you can use SQL Server as a hex editor and get it to corrupt one of its own databases.

    http://sqlblogcasts.com/blogs/tonyrogerson/archive/2007/03/10/how-to-create-a-corrupt-database-using-bulk-insert-update-and-bcp-sql-server-as-a-hex-editor.aspx

    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
  • Leo (10/16/2008)


    1. How do we know database is corrupt before the Backup at 22:00? Job is already setup and backup the corrupt database anyway according from the JOB. Any way to stop that, NOT to backup?

    You could write the results of checkDB to a table and have the backup job check that.

    2. Which command can fix and repair the Database if 'dbcc checkdb' result is failed.

    Don't repair. If all the corruption is within nonclustered indexes, you rebuild (or drop and recreate) those indexes.

    If the corruption is elsewhere, you restore the last clean backup and then roll the transaction log backups forward.

    Repair is a last-resort when there's no good backup and no other way to get data back. It doesn't always work.

    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
  • Hi Everyone,

    I bought LiteSpeed Backup, I am using it for SQL 2000 Server. Interesting thing is some function are similar with SQL 2005 maintenance plan.

    However, let me get to the point...

    I setup 3 difference maintenance plan in Litespeed - Please analyse and suggest me if I am doing something wrong

    Mon-Fri

    1.Check DB Integrity [All Database]

    2.Shrink Database [Expect System Database]

    3.Backup Database [All Database]

    4.Clean Up Maintenance Plan

    5.Clean Up History

    Sat

    1.Check DB Integrity [All Database]

    2.Rebuild Index [Expect System Database]

    3.Shrink Database [Expect System Database]

    4.Backup Database [All Database]

    5.Clean Up Maintenance Plan

    6.Clean Up History

    Sun

    1.Check DB Integrity [All Database]

    2.Reorganise Index [Expect System Database]

    3.Shrink Database [Expect System Database]

    4.Backup Database [All Database]

    5.Clean Up Maintenance Plan

    6.Clean Up History

    Other Reason I am doing 'Rebuild' and 'Reorganise' on difference day becasue it take long time to index and another reason is-

    Reorganise an index when the degree of fragmentation is between 5 and 30%

    Rebuild an index when the degree of fragmentation is over 30%

    Is that right setup?

    Thanks.

    Leo

  • You should not shrink your database on a regular scheduled basis. You should always maintain enough free space in the database to allow for index rebuilds and reorgs - as well as day to day growth.

    By shrinking your database every day - you are causing index fragmentation and file fragmentation as the database grows again.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

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

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