Blog Archives
Uniquifiers: all rows or the duplicate keys only?
Some days ago I was talking with my friend Davide Mauri about the uniquifier that SQL Server adds to clustered indexes when they are not declared as UNIQUE.
We were not completely sure whether this behaviour applied to duplicate keys only or to all keys, even when unique.
The best way to discover the truth is a script to test what happens behind the scenes:
-- ============================================= -- Author: Gianluca Sartori - @spaghettidba -- Create date: 2014-03-15 -- Description: Checks whether the UNIQUIFIER column -- is added to a column only on -- duplicate clustering keys or all -- keys, regardless of uniqueness -- ============================================= USE tempdb GO IF OBJECT_ID('sizeOfMyTable') IS NOT NULL DROP VIEW sizeOfMyTable; GO -- Create a view to query table size information -- Not very elegant, but saves a lot of typing CREATE VIEW sizeOfMyTable AS SELECT OBJECT_NAME(si.object_id) AS table_name, si.name AS index_name, SUM(total_pages) AS total_pages, SUM(used_pages) AS used_pages, SUM(data_pages) AS data_pages FROM sys.partitions AS p INNER JOIN sys.allocation_units AS AU ON P.hobt_id = AU.container_id INNER JOIN sys.indexes AS si ON si.index_id = p.index_id AND si.object_id = p.object_id WHERE si.object_id = OBJECT_ID('#testUniquifier') GROUP BY OBJECT_NAME(si.object_id), si.name GO IF OBJECT_ID('#testUniquifier') IS NOT NULL DROP TABLE #testUniquifier; -- Create a test table CREATE TABLE #testUniquifier ( i int NOT NULL ) -- Results table: will receive table size -- in different scenarios DECLARE @results TABLE( description varchar(500), table_name sysname, index_name sysname, total_pages int, used_pages int, data_pages int ); -- INSERTS 100K UNIQUE VALUES INSERT INTO #testUniquifier SELECT TOP(100000) ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) FROM sys.all_columns AS AC CROSS JOIN sys.all_columns AS AC1; -- ----------------------------------------------------------------- -- TEST1: CREATES A UNIQUE CLUSTERED INDEX (NO UNIQUIFIER) -- ----------------------------------------------------------------- CREATE UNIQUE CLUSTERED INDEX UK_test ON #testUniquifier(i); INSERT @results SELECT 'Unique clustered index' AS description, * FROM sizeOfMyTable; DROP INDEX UK_test ON #testUniquifier -- ----------------------------------------------------------------- -- TEST2: CREATES A NON-UNIQUE CLUSTERED INDEX -- NO DUPLICATES ARE PRESENT YET -- ----------------------------------------------------------------- CREATE CLUSTERED INDEX IX_test ON #testUniquifier(i) INSERT @results SELECT 'Non-Unique clustered index, no duplicates' AS description, * FROM sizeOfMyTable DROP INDEX IX_test ON #testUniquifier -- ----------------------------------------------------------------- -- TEST3: CREATES A NON-UNIQUE CLUSTERED INDEX -- 10000 DUPLICATE VALUES ARE PRESENT -- ----------------------------------------------------------------- UPDATE TOP(10000) #testUniquifier SET i = 1 CREATE CLUSTERED INDEX IX_test ON #testUniquifier(i) INSERT @results SELECT 'Non-Unique clustered index, some duplicates' AS description, * FROM sizeOfMyTable DROP INDEX IX_test ON #testUniquifier -- ----------------------------------------------------------------- -- TEST4: CREATES A NON-UNIQUE CLUSTERED INDEX -- ALL ROWS CONTAIN THE SAME VALUE (1) -- ----------------------------------------------------------------- UPDATE #testUniquifier SET i = 1 CREATE CLUSTERED INDEX IX_test ON #testUniquifier(i) INSERT @results SELECT 'Non-Unique clustered index, all duplicates' AS description, * FROM sizeOfMyTable -- ----------------------------------------------------------------- -- Display results -- ----------------------------------------------------------------- SELECT * FROM @results;
As you can see, the uniquifier is added only to the keys that are duplicated:
Another way to discover the same results would be looking at the output of DBCC PAGE().
Looking at the text output of DBCC PAGE, uniquifiers are displayed as 0 (zero) when the values are not set, but the values are actually missing from the page.
This becomes even clearer when using DBCC PAGE WITH TABLERESULTS:
IF OBJECT_ID('tempdb..#formatteddata') IS NOT NULL DROP TABLE #formatteddata; SELECT *, ROWNUM = ROW_NUMBER() OVER (ORDER BY page_id, slot_id) INTO #formatteddata FROM #testUniquifier CROSS APPLY sys.fn_PhysLocCracker(%%physloc%%); IF OBJECT_ID('tempdb..#dbccpage') IS NOT NULL DROP TABLE #dbccpage; CREATE TABLE #dbccpage ( page_id int, ParentObject varchar(128), Object varchar(128), Field varchar(128), value varchar(4000), Slot AS SUBSTRING(Object, NULLIF(CHARINDEX('Slot ',Object,1),0) + 5, ISNULL(NULLIF(CHARINDEX(' ',Object,6),0),0) - 5) ) DECLARE @current_page_id int; DECLARE pages CURSOR STATIC LOCAL FORWARD_ONLY READ_ONLY FOR SELECT DISTINCT page_id FROM #formatteddata OPEN pages FETCH NEXT FROM pages INTO @current_page_id WHILE @@FETCH_STATUS = 0 BEGIN INSERT INTO #dbccpage (ParentObject, Object, Field, value) EXEC sp_executesql N'DBCC PAGE (2, 1, @pageid, 3) WITH TABLERESULTS;', N'@pageid int', @current_page_id UPDATE #dbccpage SET page_id = @current_page_id WHERE page_id IS NULL FETCH NEXT FROM pages INTO @current_page_id END CLOSE pages; DEALLOCATE pages; WITH PageData AS ( SELECT page_id, slot, field, value FROM #dbccpage WHERE field IN ('i', 'UNIQUIFIER') ), Uniquifiers AS ( SELECT * FROM PageData PIVOT (MAX(value) FOR field IN ([i], [UNIQUIFIER])) AS pvt ), sourceData AS ( SELECT * FROM #formatteddata ) SELECT src.ROWNUM, src.i, src.page_id, src.slot_id, UNIQUIFIER FROM sourceData AS src LEFT JOIN Uniquifiers AS unq ON src.slot_id = unq.slot AND src.page_id = unq.page_id ORDER BY ROWNUM;
If you run the code in the different situations outlined before (unique clustered index, non-unique clustered index with or without duplicate keys) you will find the uniquifiers associated with each duplicate key and you will also notice that no uniquifier is generated for the keys that are unique.
Discovering resultset definition of DBCC commands in SQL Server 2012
Back in 2011 I showed a method to discover the resultset definition of DBCC undocumented commands.
At the time, SQL Server 2012 had not been released yet and nothing suggested that the linked server trick could stop working on the new major version. Surprisingly enough it did.
If you try to run the same code showed in that old post on a 2012 instance, you will get a quite explicit error message:
DECLARE @srv nvarchar(4000); SET @srv = @@SERVERNAME; -- gather this server name -- Create the linked server EXEC master.dbo.sp_addlinkedserver @server = N'LOOPBACK', @srvproduct = N'SQLServ', -- it’s not a typo: it can’t be “SQLServer” @provider = N'SQLNCLI', -- change to SQLOLEDB for SQLServer 2000 @datasrc = @srv; -- Set the authentication to "current security context" EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = N'LOOPBACK', @useself = N'True', @locallogin = NULL, @rmtuser = NULL, @rmtpassword = NULL; USE tempdb; GO CREATE PROCEDURE loginfo AS BEGIN SET NOCOUNT ON; DBCC LOGINFO(); END GO SELECT * INTO tempdb.dbo.loginfo_output FROM OPENQUERY(LOOPBACK, 'SET FMTONLY OFF; EXEC tempdb.dbo.loginfo'); DROP PROCEDURE loginfo; GO
Msg 11528, Level 16, State 1, Procedure sp_describe_first_result_set, Line 1 The metadata could not be determined because statement 'DBCC LOGINFO();' in procedure 'loginfo' does not support metadata discovery.
This behaviour has to do with the way SQL Server 2012 tries to discover metadata at parse/bind time, when the resultset is not available yet for DBCC commands.
Fortunately, there is still a way to discover metadata when you have a SQL Server instance of a previous version available.
On my laptop I have a 2008R2 instance I can use to query the 2012 instance with a linked server:
-- run this on the 2008R2 instance USE [master] GO EXEC master.dbo.sp_addlinkedserver @server = N'LOCALHOST\SQL2012' ,@srvproduct = N'SQL Server' EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = N'LOCALHOST\SQL2012' ,@useself = N'True' ,@locallogin = NULL ,@rmtuser = NULL ,@rmtpassword = NULL GO SELECT * INTO tempdb.dbo.loginfo_output FROM OPENQUERY([LOCALHOST\SQL2012], 'SET FMTONLY OFF; EXEC tempdb.dbo.loginfo'); GO
This code pipes the results of the DBCC command into a table in the tempdb database in my 2008R2 instance. The table can now be scripted using SSMS:
Using the 2008R2 instance as a “Trojan Horse” for the metadata discovery, you can see that the resultset definition of DBCC LOGINFO() has changed again in SQL Server 2012:
CREATE TABLE [dbo].[loginfo_output]( [RecoveryUnitId] [int] NULL, -- new in SQL2012 [FileId] [int] NULL, [FileSize] [bigint] NULL, [StartOffset] [bigint] NULL, [FSeqNo] [int] NULL, [Status] [int] NULL, [Parity] [tinyint] NULL, [CreateLSN] [numeric](25, 0) NULL )
This trick will be particularly useful for an upcoming (and long overdue) post, so… stay tuned!
Setting up an e-mail alert for DBCC CHECKDB errors
Some months ago I posted a script on a SQLServerCentral forum to help a member automating the execution of DBCC CHECKDB and send and e-mail alert in case a consistency error is found.
The original thread can be found here.
I noticed that many people are actually using that script and I also got some useful feedback on the code itself, so I decided to write this post to make an enhanced version available to everyone.
The Problem
Your primary responsibility as a DBA is to safeguard your data with backups. I mean intact backups! Keep in mind that when you back up a corrupt database, you will also restore a corrupt database.
A task that checks the database integrity should be part of your backup strategy and you should be notified immediately when corruption is found.
Unfortunately, the built-in consistency check Maintenance Task does not provide an alerting feature and you have to code it yourself.
The Solution
SQL Server 2000 and above accept the “WITH TABLERESULTS” option for most DBCC commands to output the messages as a result set. Those results can be saved to a table and processed to identify messages generated by corrupt data and raise an alert.
If you don’t know how to discover the resultset definition of DBCC CHECKDB WITH TABLERESULTS, I suggest that you take a look at this post.
Here is the complete code of the stored procedure I am using on my production databases:
-- https://spaghettidba.com/2011/11/28/email-alert-dbcc-checkdb/ | |
-- You have a TOOLS database, don't you? | |
-- If not, create it: you'll thank me later. | |
USE TOOLS; | |
GO | |
IF NOT EXISTS( SELECT 1 FROM sys.schemas WHERE name = 'maint') | |
EXEC('CREATE SCHEMA maint'); | |
GO | |
-- ============================================= | |
-- Author: Gianluca Sartori - spaghettidba | |
-- Create date: 2011-06-30 | |
-- Description: Runs DBCC CHECKDB on the database(s) specified | |
-- and returns a table result that can be used in | |
-- reporting and alerting. | |
-- ============================================= | |
CREATE PROCEDURE [maint].[dba_runCHECKDB] | |
@dbName nvarchar(max) = NULL, -- Database name. If NULL, will check all databases | |
@PHYSICAL_ONLY bit = 0, -- Set to 1 to perform physical check only. Defaults to 0. | |
@allMessages bit = 0, -- Set to 1 to return all the messages generated by DBCC | |
-- Set to 0 to return one summary message for each database (default) | |
@dbmail_profile sysname = NULL, -- DBMail profile to use when sending the results | |
@dbmail_recipient sysname = NULL, -- DBMail recipient | |
@log_to_table bit = 0, -- Set to 1 to enable logging to table DBCC_CHECKDB_HISTORY | |
@help bit = 0 | |
AS | |
BEGIN | |
SET NOCOUNT, | |
XACT_ABORT, | |
QUOTED_IDENTIFIER, | |
ANSI_NULLS, | |
ANSI_PADDING, | |
ANSI_WARNINGS, | |
ARITHABORT, | |
CONCAT_NULL_YIELDS_NULL ON; | |
SET NUMERIC_ROUNDABORT OFF; | |
IF @help = 1 | |
BEGIN | |
SELECT * | |
FROM ( | |
SELECT '@dbname nvarchar(max) = NULL','Database name.' | |
UNION ALL SELECT '','''Database'' checks a single database' | |
UNION ALL SELECT '','NULL checks all databases' | |
UNION ALL SELECT '','''Database1,Database2,...DatabaseN'' checks the databases in the list' | |
UNION ALL SELECT '','''^Database1,^Database2,...^DatabaseN'' checks all databases except the ones in the list' | |
UNION ALL SELECT '','Combinations of positive (not prefixed with ^) and negative (prefixed with ^) elements' | |
UNION ALL SELECT '','considers positive elements only. Use negative elements alone.' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@PHYSICAL_ONLY bit = 0','If set to 1, performs CHECKDB WITH PHYSICAL_ONLY' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@allMessages bit = 0','If set to 1, returns all the messages generated by DBCC' | |
UNION ALL SELECT '','If set to 0, returns a summary message for each database' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@dbmail_profile sysname = NULL','The dbmail profile to use to send out the email.' | |
UNION ALL SELECT '','NULL uses the global dbmail profile' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@dbmail_recipient sysname = NULL','The address that will receive the email.' | |
UNION ALL SELECT '','If set to NULL disables sending the email and returns a result set.' | |
UNION ALL SELECT '','If not NULL sends the email without returning a result set' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@log_to_table bit = 0','If set to 1, stores the results in the table DBCC_CHECKDB_HISTORY.' | |
UNION ALL SELECT '','If the table does not exists, it will create the table for you.' | |
UNION ALL SELECT '','When logging to a table, a result set is not returned.' | |
UNION ALL SELECT '','' | |
UNION ALL SELECT '@help bit = 0','If set to 1 displays this help.' | |
) AS h ( | |
[-----parameter------------------------------------------------------] | |
,[-----description----------------------------------------------------------------------------------------------------------------] | |
) | |
RETURN | |
END | |
DECLARE @version int | |
DECLARE @sql nvarchar(4000) | |
DECLARE @ErrorMessage nvarchar(2048) | |
DECLARE @body nvarchar(max) | |
DECLARE @Message nvarchar(4000) | |
DECLARE @Severity int | |
DECLARE @State int | |
-- determine major version: DBCC output can be different | |
SELECT @version = CAST(REPLACE(CAST(SERVERPROPERTY('ProductVersion') AS char(2)),'.','') AS int) | |
-- Clean up the @dbname parameter | |
-- Remove leading/trailing spaces | |
SET @dbname = LTRIM(RTRIM(@dbname)) | |
-- Remove leading commas | |
WHILE LEFT(@dbname,1) = ',' | |
SET @dbname = SUBSTRING(@dbname, 2, LEN(@dbname)) | |
-- Remove trailing commas | |
WHILE RIGHT(@dbname,1) = ',' | |
SET @dbname = SUBSTRING(@dbname, 1, LEN(@dbname)-1) | |
IF OBJECT_ID('tempdb..##DBCC_OUTPUT') IS NOT NULL | |
DROP TABLE ##DBCC_OUTPUT | |
-- SQL2005, SQL2008, SQL2008R2 produce this output | |
-- except for the columns explicitly marked as new in SQL 2012 | |
CREATE TABLE ##DBCC_OUTPUT( | |
Error int NULL, | |
[Level] int NULL, | |
State int NULL, | |
MessageText nvarchar(2048) NULL, | |
RepairLevel nvarchar(22) NULL, | |
Status int NULL, | |
DbId int NULL, -- was smallint in SQL2005 | |
DbFragId int NULL, -- new in SQL2012 | |
ObjectId int NULL, | |
IndexId int NULL, | |
PartitionId bigint NULL, | |
AllocUnitId bigint NULL, | |
RidDbId smallint NULL, -- new in SQL2012 | |
RidPruId smallint NULL, -- new in SQL2012 | |
[File] smallint NULL, | |
Page int NULL, | |
Slot int NULL, | |
RefDbId smallint NULL, -- new in SQL2012 | |
RefPruId smallint NULL, -- new in SQL2012 | |
RefFile smallint NULL, | |
RefPage int NULL, | |
RefSlot int NULL, | |
Allocation smallint NULL | |
) | |
-- Add a computed column | |
ALTER TABLE ##DBCC_OUTPUT ADD Outcome AS | |
CASE | |
WHEN Error = 8989 AND MessageText LIKE '%0 allocation errors and 0 consistency errors%' THEN 0 | |
WHEN Error <> 8989 THEN NULL | |
ELSE 1 | |
END | |
-- Add an identity column to sort results when sending the email | |
ALTER TABLE ##DBCC_OUTPUT ADD RowId int IDENTITY(1,1) | |
DECLARE @localTran bit | |
IF @@TRANCOUNT = 0 | |
BEGIN | |
SET @localTran = 1 | |
BEGIN TRANSACTION LocalTran | |
END | |
BEGIN TRY | |
-- Create the history table if needed | |
IF @log_to_table = 1 | |
AND OBJECT_ID('maint.DBCC_CHECKDB_HISTORY') IS NULL | |
BEGIN | |
SELECT TOP(0) | |
RowId, | |
Error, | |
[Level], | |
State, | |
MessageText, | |
RepairLevel, | |
Status, | |
DbId, | |
DbFragId, | |
CAST(NULL AS sysname) AS DatabaseName, | |
ObjectId, | |
IndexId, | |
PartitionId, | |
AllocUnitId, | |
RidDbId, | |
RidPruId, | |
[File], | |
Page, | |
Slot, | |
RefDbId, | |
RefPruId, | |
RefFile, | |
RefPage, | |
RefSlot, | |
Allocation, | |
Outcome, | |
GETDATE() AS RunDate | |
INTO maint.DBCC_CHECKDB_HISTORY | |
FROM ##DBCC_OUTPUT | |
ALTER TABLE maint.DBCC_CHECKDB_HISTORY | |
ADD CONSTRAINT PK_DBCC_CHECKDB_HISTORY PRIMARY KEY CLUSTERED(RowId) | |
END | |
-- Open a cursor on the matching databases (version dependant) | |
DECLARE c_databases CURSOR LOCAL FAST_FORWARD | |
FOR | |
SELECT QUOTENAME(name) AS name | |
FROM master.sys.databases | |
WHERE ( | |
@dbname IS NULL | |
OR ',' + @dbname + ',' NOT LIKE '%,[^!^]%' ESCAPE '!' | |
OR ',' + @dbname + ',' LIKE '%,' + name + ',%' | |
OR ',' + @dbname + ',' LIKE '%,' + REPLACE(QUOTENAME(name),'[','[[]') + ',%' | |
) | |
AND ',' + ISNULL(@dbname,'') + ',' NOT LIKE '%,!^' + name + ',%' ESCAPE '!' | |
AND ',' + ISNULL(@dbname,'') + ',' NOT LIKE '%,!^' + REPLACE(QUOTENAME(name),'[','[[]') + ',%' ESCAPE '!' | |
AND state_desc = 'ONLINE' | |
AND is_read_only = 0 | |
AND source_database_id IS NULL -- Exclude Snapshots | |
AND name <> 'tempdb' | |
OPEN c_databases | |
FETCH NEXT FROM c_databases INTO @dbName | |
WHILE @@FETCH_STATUS = 0 | |
BEGIN | |
-- Build a SQL string | |
SET @sql = 'DBCC CHECKDB('+ @dbName +') WITH TABLERESULTS, ALL_ERRORMSGS ' | |
IF @PHYSICAL_ONLY = 1 | |
SET @sql = @sql + ', PHYSICAL_ONLY ' | |
BEGIN TRY | |
IF @version > 8 AND @version < 11 | |
BEGIN | |
-- SQL2005/2008 use this column list | |
INSERT INTO ##DBCC_OUTPUT ( | |
Error, | |
[Level], | |
State, | |
MessageText, | |
RepairLevel, | |
Status, | |
DbId, | |
ObjectId, | |
IndexId, | |
PartitionId, | |
AllocUnitId, | |
[File], | |
Page, | |
Slot, | |
RefFile, | |
RefPage, | |
RefSlot, | |
Allocation | |
) | |
EXEC(@sql) | |
END | |
IF @version >= 11 | |
BEGIN | |
-- SQL2012 uses all columns | |
INSERT INTO ##DBCC_OUTPUT ( | |
Error, | |
[Level], | |
State, | |
MessageText, | |
RepairLevel, | |
Status, | |
DbId, | |
DbFragId, | |
ObjectId, | |
IndexId, | |
PartitionId, | |
AllocUnitId, | |
RidDbId, | |
RidPruId, | |
[File], | |
Page, | |
Slot, | |
RefDbId, | |
RefPruId, | |
RefFile, | |
RefPage, | |
RefSlot, | |
Allocation | |
) | |
EXEC(@sql) | |
END | |
END TRY | |
BEGIN CATCH | |
SELECT @ErrorMessage = 'Unable to run DBCC on database ' + @dbName + ': ' + ERROR_MESSAGE() | |
INSERT INTO ##DBCC_OUTPUT (Error, MessageText) | |
SELECT Error = 8989, | |
MessageText = @ErrorMessage | |
END CATCH | |
FETCH NEXT FROM c_databases INTO @dbName | |
END | |
CLOSE c_databases | |
DEALLOCATE c_databases | |
IF NOT EXISTS ( | |
SELECT 1 FROM ##DBCC_OUTPUT | |
) | |
BEGIN | |
RAISERROR('No database matches the name specified.',10,1) | |
END | |
IF @log_to_table = 1 | |
BEGIN | |
INSERT INTO maint.DBCC_CHECKDB_HISTORY ( | |
Error, | |
[Level], | |
State, | |
MessageText, | |
RepairLevel, | |
Status, | |
DbId, | |
DbFragId, | |
DatabaseName, | |
ObjectId, | |
IndexId, | |
PartitionId, | |
AllocUnitId, | |
RidDbId, | |
RidPruId, | |
[File], | |
Page, | |
Slot, | |
RefDbId, | |
RefPruId, | |
RefFile, | |
RefPage, | |
RefSlot, | |
Allocation, | |
Outcome, | |
RunDate | |
) | |
SELECT | |
Error, | |
[Level], | |
State, | |
MessageText, | |
RepairLevel, | |
Status, | |
DbId, | |
DbFragId, | |
DatabaseName = ISNULL(DB_NAME(DbId),'resourcedb'), | |
ObjectId, | |
IndexId, | |
PartitionId, | |
AllocUnitId, | |
RidDbId, | |
RidPruId, | |
[File], | |
Page, | |
Slot, | |
RefDbId, | |
RefPruId, | |
RefFile, | |
RefPage, | |
RefSlot, | |
Allocation, | |
Outcome, | |
RunDate = GETDATE() | |
FROM ##DBCC_OUTPUT | |
WHERE Error = 8989 | |
OR @allMessages = 1 | |
OR DbId IN ( | |
SELECT DbId | |
FROM ##DBCC_OUTPUT | |
WHERE Error = 8989 | |
AND Outcome = 1 | |
) | |
END | |
-- Build the final SQL statement | |
SET @sql = | |
'SELECT ISNULL(DB_NAME(DbId),''resourcedb'') AS DatabaseName, ' + | |
CASE @allMessages | |
WHEN 1 THEN '*' | |
ELSE 'MessageText, Outcome' | |
END + ' | |
FROM ##DBCC_OUTPUT | |
WHERE 1 = 1 ' + | |
CASE @allMessages WHEN 1 THEN '' ELSE 'AND Error = 8989' END | |
IF @dbmail_recipient IS NULL | |
BEGIN | |
-- Query DBCC output directly | |
EXEC(@sql) | |
END | |
ELSE | |
BEGIN | |
-- Pipe DBCC output to a variable | |
SET @sql = ' | |
SELECT @body = ( | |
SELECT ISNULL(MessageText,'''') + char(10) AS [text()] | |
FROM ( ' + @sql + ' AND Error = 8989 ) AS src | |
WHERE Outcome = 1 | |
ORDER BY 1 DESC | |
FOR XML PATH('''') | |
)' | |
EXEC sp_executesql @sql, N'@body nvarchar(max) OUTPUT', @body OUTPUT | |
-- Send CHECKDB report | |
IF @body IS NOT NULL | |
BEGIN | |
EXEC msdb.dbo.sp_send_dbmail | |
@profile_name = @dbmail_profile, | |
@recipients = @dbmail_recipient, | |
@subject = 'Consistency error found!', | |
@body = @body, | |
@importance = 'High', | |
@query = ' | |
SET NOCOUNT ON; | |
SELECT TOP(5000) ISNULL(DB_NAME(DbId),''resourcedb'') + '' -'' AS DatabaseName, MessageText | |
FROM ##DBCC_OUTPUT WITH (NOLOCK) | |
WHERE DbId IN ( | |
SELECT DbId | |
FROM ##DBCC_OUTPUT WITH (NOLOCK) | |
WHERE Error = 8989 | |
AND Outcome = 1 | |
) | |
ORDER BY RowId ASC ', | |
@attach_query_result_as_file = 1, | |
@query_result_no_padding = 1, | |
@query_result_header = 0, | |
@exclude_query_output = 1, | |
@query_attachment_filename = 'DBCC_CHECKDB_Errors.log' | |
END | |
END | |
IF @localTran = 1 AND XACT_STATE() = 1 | |
COMMIT TRAN LocalTran | |
IF OBJECT_ID('tempdb..##DBCC_OUTPUT') IS NOT NULL | |
DROP TABLE ##DBCC_OUTPUT | |
END TRY | |
BEGIN CATCH | |
SELECT @Message = ERROR_MESSAGE(), | |
@Severity = ERROR_SEVERITY(), | |
@State = ERROR_STATE() | |
IF @localTran = 1 AND XACT_STATE() <> 0 | |
ROLLBACK TRAN | |
RAISERROR ( @Message, @Severity, @State) | |
END CATCH | |
END |
Once the stored procedure is ready, you can run it against the desired databases:
EXEC [maint].[dba_runCHECKDB] @dbName = 'model', @PHYSICAL_ONLY = 0, @allmessages = 0
Setting up an e-mail alert
In order to receive an e-mail alert, you can use a SQL Agent job and schedule this script to run every night, or whenever you find appropriate.
EXEC [maint].[dba_runCHECKDB] @dbName = NULL, @PHYSICAL_ONLY = 0, @allmessages = 0, @dbmail_profile = 'DBA_profile', @dbmail_recipient = 'dba@mycompany.com'
The e-mail message generated by the stored procedure contains the summary outcome and a detailed log, attached as a text file:
Logging to a table
If needed, you can save the output of this procedure to a history table that logs the outcome of DBCC CHECKDB in time:
-- Run the stored procedure with @log_to_table = 1 EXEC TOOLS.maint.dba_runCHECKDB @dbName = NULL, @PHYSICAL_ONLY = 0, @allMessages = 0, @log_to_table = 1 -- Query the latest results SELECT * FROM ( SELECT *, RN = ROW_NUMBER() OVER (PARTITION BY DBId ORDER BY RunDate DESC) FROM DBCC_CHECKDB_HISTORY WHERE Outcome IS NOT NULL ) AS dbcc_history WHERE RN = 1
When invoked with the @log_to_table parameter for the first time, the procedure creates a log table that will be used to store the results. Subsequent executions will append to the table.
No excuses!
The web is full of blogs, articles and forums on how to automate DBCC CHECKDB. If your data has any value to you, CHECKDB must be part of your maintenance strategy.
Run! Check the last time you performed a successful CHECKDB on your databases NOW! Was it last year? You may be in big trouble.
Discovering resultset definition of DBCC commands
Lots of blog posts and discussion threads suggest piping the output of DBCC commands to a table for further processing. That’s a great idea, but, unfortunately, an irritatingly high number of those posts contains an inaccurate table definition for the command output.
The reason behind this widespread inaccuracy is twofold.
On one hand the output of many DBCC commands changed over time and versions of SQL Server, and a table that was the perfect fit for the command in SQL Server 2000 is not perfect any more. In this case, the blog/article/thread is simply old, but many people will keep referring to that source assuming that things did not change.
On the other hand, the output is not always documented in BOL, and people often have to guess the table definition based on the data returned by the command. I’ve been guilty of this myself and I’ve been corrected many times, until I decided that I needed a better way to discover the output definition.
You are a database professional and you don’t like to guess, because guessing is never as good as knowing it for sure.
In order to stop guessing, you will have to create a linked server named “loopback” that points back to the same instance where you are running the DBCC command.
I am sure you are asking yourself why you need such a strange thing as a loopback linked server. The idea behind is that you need a way to query the command as if it was a table or a view, so that it can be used as a valid source for a SELECT…INTO statement. The perfect tool for this kind of task is the OPENQUERY command, which allows sending pass-through queries, that don’t necessarily need to be SELECT statements. OPENQUERY requires a linked server, which can be any OLEDB data source, including a remote server or the same SQL Server instance where the linked server lies.
OK, let’s create it:
DECLARE @srv nvarchar(4000); SET @srv = @@SERVERNAME; -- gather this server name -- Create the linked server EXEC master.dbo.sp_addlinkedserver @server = N'LOOPBACK', @srvproduct = N'SQLServ', -- it’s not a typo: it can’t be “SQLServer” @provider = N'SQLNCLI', -- change to SQLOLEDB for SQLServer 2000 @datasrc = @srv; -- Set the authentication to "current security context" EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = N'LOOPBACK', @useself = N'True', @locallogin = NULL, @rmtuser = NULL, @rmtpassword = NULL;
In order to capture the output of DBCC commands, you have to wrap them inside a stored procedure, otherwise SQL Server could complain about missing column information. I don’t know the exact technical reason behind this error (I suppose it has to do with the way metadata is propagated), but this limitation can be overcome wrapping the command into a stored procedure and using “SET FMTONLY OFF” in the pass-through query.
This is also a nice way to overcome the single INSERT…EXEC limit (and implement many more interesting tricks that I hope to cover in future posts).
For instance, to capture the table definition of DBCC LOGINFO(), you will have to create a stored procedure similar to this:
USE tempdb; GO CREATE PROCEDURE loginfo AS BEGIN SET NOCOUNT ON; DBCC LOGINFO(); END GO
With the stored procedure and the linked server in place, you can set up the call using OPENQUERY:
SELECT * INTO tempdb.dbo.loginfo_output FROM OPENQUERY(LOOPBACK, 'SET FMTONLY OFF; EXEC tempdb.dbo.loginfo'); DROP PROCEDURE loginfo; GO
Running this script will create a table named “loginfo_output” in the tempdb database: you can find it in your object explorer and script it out to a new query editor window.
Repeating these steps on instances running different versions on SQL Server reveals that the table definition changed in SQL2005 and then remained the same in 2008 and 2008R2.
-- SQL Server 2000 CREATE TABLE [dbo].[loginfo_output]( [FileId] [int] NULL, [FileSize] [numeric](20, 0) NULL, [StartOffset] [numeric](20, 0) NULL, [FSeqNo] [int] NULL, [Status] [int] NULL, [Parity] [tinyint] NULL, [CreateLSN] [numeric](25, 0) NULL ) -- SQL Server 2005, 2008 and 2008R2 CREATE TABLE [dbo].[loginfo_output]( [FileId] [int] NULL, [FileSize] [bigint] NULL, [StartOffset] [bigint] NULL, [FSeqNo] [int] NULL, [Status] [int] NULL, [Parity] [tinyint] NULL, [CreateLSN] [numeric](25, 0) NULL )
Now that you know how the output looks like, you can happily pipe the results of DBCC LOGINFO to an appropriate table:
-- Declare variable for dynamic sql DECLARE @sql nvarchar(max) -- Drop the table if already exists IF OBJECT_ID('tempdb..loginfo_output') IS NOT NULL DROP TABLE tempdb..loginfo_output -- Check SQL Server version IF CAST(REPLACE(LEFT(CAST(SERVERPROPERTY('ProductVersion') AS nvarchar(128)),2),'.','') AS int) > 8 BEGIN -- SQL Server 2005+ SET @sql = ' CREATE TABLE tempdb..loginfo_output( [FileId] [int] NULL, [FileSize] [bigint] NULL, [StartOffset] [bigint] NULL, [FSeqNo] [int] NULL, [Status] [int] NULL, [Parity] [tinyint] NULL, [CreateLSN] [numeric](25, 0) NULL ) ' END ELSE BEGIN -- SQL Server 2000 SET @sql = ' CREATE TABLE tempdb..loginfo_output( [FileId] [int] NULL, [FileSize] [numeric](20, 0) NULL, [StartOffset] [numeric](20, 0) NULL, [FSeqNo] [int] NULL, [Status] [int] NULL, [Parity] [tinyint] NULL, [CreateLSN] [numeric](25, 0) NULL ) ' END -- Create the output table EXEC(@sql) -- Execute DBCC command and -- pipe results to the output table INSERT tempdb..loginfo_output EXEC('DBCC LOGINFO()') -- Display results SELECT * FROM tempdb..loginfo_output
You could ask with good reason why you should use an output table when you could query the wrapper stored procedure directly with OPENQUERY. Based on observation, the trick does not always work and SQL Server can randomly complain about missing column information.
Msg 7357, Level 16, State 2, Line 2 Cannot process the object "loginfo". The OLE DB provider "SQLNCLI10" for linked server "LOOPBACK" indicates that either the object has no columns or the current user does not have permissions on that object.
Again, I don’t have an in-depth technical answer: I can only report what I observed. It’s not a big deal indeed, because the output definition changes very slowly (typically between SQL Server versions) and you probably would review your code anyway when upgrading to a newer version. I guess you can live with a hardcoded table definition when the price to pay for having it dynamic is a random failure.
This post showed you how to capture the output of DBCC LOGINFO, but the same technique can be used for all DBCC commands that allow specifying WITH TABLERESULTS, extended stored procedures, remote stored procedures and all those programmable objects than cannot be inspected easily.
Now that you have the right tool in your hands, do yourself a favour: stop guessing!