Disk space issues during DBCC CHECKDB
Sometimes an issue arises when the hidden database snapshot runs out of space. Because it’s implemented using alternate streams of the existing data files, the database snapshot consumes space from the same location as the existing data files. If the database being checked has a heavy update workload, more and more pages are pushed into the database snapshot, causing it to grow. In a situation where the volumes hosting the database don’t have much space, this can mean the hidden database snapshot runs out of space and DBCC CHECKDB stops with an error. An example of this is shown here (the errors can vary depending on the exact point at which the database snapshot runs out of space):DBCC CHECKDB ('SalesDB2') WITH NO_INFOMSGS, ALL_ERRORMSGS;
GO
Msg 1823, Level 16, State 1, Line 5
A database snapshot cannot be created because it failed to start.
Msg 1823, Level 16, State 2, Line 1
A database snapshot cannot be created because it failed to start.
Msg 7928, Level 16, State 1, Line 1
The database snapshot for online checks could not be created. Either the reason is given in a previous error or one of the underlying volumes does not support sparse files or alternate streams. Attempting to get exclusive access to run checks offline.
Msg 5128, Level 17, State 2, Line 1
Write to sparse file 'C:\SQLskills\SalesDBData.mdf:MSSQL_DBCC20' failed due to lack of disk space.
Msg 3313, Level 21, State 2, Line 1
During redoing of a logged operation in database 'SalesDB2', an error occurred at log record ID (1628:252:1). Typically, the specific failure is previously logged as an error in the Windows Event Log service. Restore the database from a full backup, or repair the database.
Msg 0, Level 20, State 0, Line 0
A severe error occurred on the current command. The results, if any, should be discarded.
In this case, the solution is to create your own database snapshot, placing the snapshot files on a volume with more disk space, and then to run DBCC CHECKDB on that. DBCC CHECKDB recognizes that it’s already running on a database snapshot and doesn’t attempt to create another one. If a database snapshot was created by DBCC CHECKDB, it’s discarded automatically after the consistency-checking algorithms are complete.
While it runs, DBCC CHECKDB creates a database snapshot (if needed) and suspends the FILESTREAM garbage collection process. You might notice garbage collection run at the start of the consistency checking process; the creation of the hidden database snapshot starts with a checkpoint, which is what triggers FILESTREAM garbage collection. The suspension of garbage collection activity allows the consistency-checking algorithms to see a transactionally consistent view of the FILESTREAM data on any FILESTREAM data containers
Alternatives to using a database snapshot
A database snapshot isn’t required under the following conditions.
- The specified database is a database snapshot itself.
- The specified database is read-only, in single-user mode, or in emergency mode.
- The server was started in single-user mode with the –m command-line option.
In these cases, the database is already essentially consistent because no other active connections can be making changes that would break the consistency checks.
A database snapshot can’t be created under the following conditions.
- The specified database is stored on a non–NTFS file system, in which case a database snapshot can’t be created because it relies on NTFS sparse-file technology.
- The specified database is tempdb, because a database snapshot can’t be created on tempdb.
- The TABLOCK option was specified.
If a database snapshot can’t be created for any reason, DBCC CHECKDB attempts to use locks to obtain a transactionally consistent view of the database. First, it obtains a database-level exclusive lock so that it can perform the allocation consistency checks without any changes taking place. Offline consistency checks can’t be run on master or on tempdb because these databases can’t be exclusively locked. This means that allocation consistency checks are always skipped for tempdb (as was usually the case with SQL Server 2000, too). This also isn’t possible if the database is an Availability Group replica, in which case error 7934 is reported if the database snapshot creation fails.
Rather than wait for the exclusive lock indefinitely (or whatever the server lock timeout period has been set to), DBCC CHECKDB waits for 20 seconds (or the configured lock timeout value for the session) and then exits with the following error:
DBCC CHECKDB ('msdb') WITH TABLOCK;
GO
Msg 5030, Level 16, State 12, Line 1
The database could not be exclusively locked to perform the operation.
Msg 7926, Level 16, State 1, Line 1
Check statement aborted. The database could not be checked as a database snapshot could not be created and the database or table could not be locked. See Books Online for details of when this behavior is expected and what workarounds exist. Also see previous errors for more details.
If the lock was acquired after the allocation checks are completed, the exclusive lock is dropped and table-level share locks are acquired while the table-level logical consistency checks are performed. The same time-out applies to these table-level locks.
One way or another, DBCC CHECKDB obtains a transactionally consistent view of the database that it’s checking. After that, it can start processing the database.
Reference:Microsoft SQL Server 2012 Internals
No comments:
Post a Comment