Dbcc checkdb automation request

  • Hi guys,

    I know how important it is to run dbcc checks regularly, and to run it hassle free. I am actually trying to find out a script which can automate this task for me, and send me the reports for all the checks through mail. I need the dbcc checkdb output only if there is any errors after running consistency checks, and wouldn't really bother to get an e-mail if there is none. I also want to get a mail from all the linked servers that have been configured in my environment so that it gives me a complete list of only the error output from dbcc checkdb ignoring other messages, wherein I can quickly login to that server and rectify the things as per guidelines laid by Paul for various dbcc errors.

    I hope if somebody could point me out to some links or at best can provide me a script to do this, in case if they have implemented what I am looking for.

    Thanks,

    Faisal

  • This is something I knocked up to do the job.

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    ALTER PROCEDURE [DBCC].[InsertCheckDBDetails]

    AS

    BEGIN

    DECLARE @SQL NVARCHAR(MAX)

    SELECT @SQL = REPLACE(

    CAST(

    (

    SELECT 'USE ' + QUOTENAME(name) +';' + CHAR(13) + CHAR(10) +

    'DBCC CHECKDB WITH NO_INFOMSGS, ALL_ERRORMSGS; '

    FROM sys.databases

    FOR XML PATH('')

    )

    AS NVARCHAR(MAX)

    ),

    '&#x 0D;',CHAR(13) + CHAR(10) --REMOVE THE SPACE ON THIS LINE BETWEEN x and 0

    )

    --SELECT @SQL

    EXECUTE sp_executesql @SQL

    WAITFOR DELAY '00:01:00'

    CREATE TABLE #Error

    (

    LogDate DATETIME,

    ProcessInfo NVARCHAR(50),

    Text NVARCHAR(MAX)

    )

    INSERT INTO

    #Error

    EXEC sp_readerrorlog

    INSERT INTO

    [DBCC].CheckDBDetails

    (

    Results

    )

    SELECT

    Text

    FROM

    #Error

    WHERE

    Text LIKE 'DBCC%'

    AND

    LogDate > CONVERT(DATE,GETDATE())

    DROP TABLE #Error

    EXEC [DBCC].[CheckDBDetailsEmail]

    END

    GO

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    ALTER PROCEDURE [DBCC].[CheckDBDetailsEmail]

    AS

    BEGIN

    DECLARE @MailSubject VARCHAR(MAX)

    SET @MailSubject = 'DBCC CHECKDB results for ' + @@SERVERNAME + ' at ' + CONVERT(VARCHAR,GETDATE(),120)

    DECLARE @EmailAddress NVARCHAR(MAX)

    SELECT @EmailAddress = EmailAddress FROM CONFIG.AlertEmails WHERE Alert = 'DBCC.CheckDBDetailsEmailTrigger'

    DECLARE @EmailBody NVARCHAR(MAX) = '', @Count INT, @a INT = 1

    SELECT @Count = COUNT(*) FROM [DBCC].CheckDBDetails WHERE DateCollected = (SELECT MAX(DateCollected) FROM [DBCC].CheckDBDetails)

    WHILE @a <= @Count

    BEGIN

    ;WITH CTE AS

    (

    SELECT

    ROW_NUMBER() OVER (ORDER BY DateCollected) AS RowNum,

    Results

    FROM

    [DBCC].CheckDBDetails

    WHERE

    DateCollected = (SELECT MAX(DateCollected) FROM [DBCC].CheckDBDetails)

    )

    SELECT @EmailBody = @EmailBody + Results + CHAR(13) + CHAR(10) FROM CTE WHERE RowNum = @a

    SET @a = @a + 1

    END

    IF @EmailBody <> ''

    BEGIN

    EXEC

    msdb.dbo.sp_send_dbmail

    @profile_name = 'Instance01-SQLAlerts',

    @recipients = @EmailAddress,

    @Subject = @MailSubject,

    @Body = @EmailBody

    END

    GO

    CREATE TABLE [DBCC].[CheckDBDetails](

    [ID] [bigint] IDENTITY(1,1) NOT NULL,

    [DateCollected] [datetime] NULL,

    [Results] [nvarchar](max) NULL,

    CONSTRAINT [PK_DBCC_CheckDBDetails] PRIMARY KEY CLUSTERED

    (

    [ID] ASC

    )WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)

    )

    GO

    And a job is set the initial proc to run every day at 3am during our daily maintenance window.

    Just ensure you remove the space on the line with the comment in the code.

  • Thanks. a lot anthony.

    May I know where I can find this table "config.alertemails" mentioned with this statement "SELECT @EmailAddress = EmailAddress FROM CONFIG.AlertEmails WHERE Alert = 'DBCC.CheckDBDetailsEmailTrigger". I don't see that table anywhere in the script. Could you pls. provide the steps for executing the 2 procs.

    Any idea or any pointers from where we can get complete list of errored dbcc messages (if one exists) as a report from all the instances in the domain.

    Thanks. once again

    Regards,

    Faisal

  • Its just a table we have in our monitoring database which contains the list of email addresses for different alerts.

    So you just need to replace it with the email addresses you want to send to.

    Just schedule the first proc in a job and it will DBCC CHECKDB all DB's on the instance then send a mail

    Then use a central management server to query all your instances.

  • Great!!!

    Guys, if you have something different pls. do come up with some other useful stuffs maybe something more in t-sql or powershell. I still need to get only dbcc errored output reported from all of my linked servers.

    Thanks. anthony for providing that automation, but I still need the reporting stuff to get the errored dbcc output send to me as a report which will include all the instances in the domain instead of manually going and looking into servers for details.

    Regards,

    Faisal

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

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