sp_iqcheckdb Procedure

Checks validity of the current database. Optionally corrects allocation problems for dbspaces or databases. sp_iqcheckdb does not check a partitioned table if partitioned data exists on offline dbspaces.

sp_iqcheckdb reads all storage in the database. On successful completion, the database free list (an internal allocation map) is updated to reflect the true storage allocation for the database. sp_iqcheckdb then generates a report listing the actions it has performed.

If an error is found, sp_iqcheckdb reports the name of the object and the type of error. sp_iqcheckdb does not update the free list if errors are detected.

sp_iqcheckdb also allows you to check the consistency of a specified table, index, index type, or the entire database.

Note: sp_iqcheckdb is the user interface to the SAP Sybase IQ database consistency checker (DBCC) and is sometimes referred to as DBCC.

Syntax

sp_iqcheckdb 'mode target [ … ] [ resources resource-percent ]'

mode:
   { allocation 
   | checkverify } 
   | dropleaks

target:
   [ indextype index-type […] ]  database 
   | database resetclocks 
   | { [ indextype index-type ] […] table table-namepartition partition-name ] […] 
   | index index-name 
   |  […] dbspace  dbspace-name}
   | cache main-cache-name

There are three modes for checking database consistency, and one for resetting allocation maps. If mode and target are not both specified in the parameter string, SAP Sybase IQ returns the error message:

At least one mode and target must be specified to DBCC.

Parameter

Note: The sp_iqcheckdb parameter string must be enclosed in single quotes and cannot be greater than 255 bytes in length.

Allocation problems can be repaired in dropleaks mode.

Applies to

Simplex and multiplex.

Privileges

You must have EXECUTE privilege on the system procedure, as well as the ALTER DATABASE system privilege.

Remarks

sp_iqcheckdb checks the allocation of every block in the database and saves the information in the current session until the next sp_iqdbstatistics procedure is issued. sp_iqdbstatistics displays the latest result from the most recent execution of sp_iqcheckdb.

sp_iqcheckdb can perform several different functions, depending on the parameters specified.

Mode Description
Allocation

Checks allocation with blockmap information for the entire database, a specific index, a specific index type, a specific partition, specific table, or a specific dbspace. Does not check index consistency.

Detects duplicate blocks (blocks for which two or more objects claim ownership) or extra blocks (unallocated blocks owned by an object).

Detects leaked blocks (allocated blocks unclaimed by any object in the specified target) for database or dbspace targets.

When the target is a partitioned table, allocation mode:
  • Checks metadata of all the table’s partition allocation bitmaps
  • Checks metadata of the tables allocation bitmap
  • Verifies that blockmap entries are consistent with the table’s allocation bitmap
  • Verifies that none of the table’s partition allocation bitmaps overlap
  • Checks that rows defined in the table’s partition allocation bitmaps form a superset of the table’s existence bitmap
  • Checks that rows defined in the table’s partition allocation bitmaps form a superset of the table’s allocation bitmap
  • Verifies that the main cache pages are consistent with the IQ main store pages.
Note: sp_iqcheckdb cannot check all allocation problems if you specify the name of a single index, index type, or table in the input parameter string.
Run in allocation mode:
  • To detect duplicate or unowned blocks (use database or specific tables or indexes as the target)
  • If you encounter page header errors

The DBCC option resetclocks is used only with allocation mode. resetclocks is used with forced recovery to convert a multiplex secondary server to a coordinator. For information on multiplex capability, see Administration: Multiplex. resetclocks corrects the values of internal database versioning clocks, in the event that these clocks are behind. Do not use the resetclocks option for any other purpose, unless you contact SAP Sybase IQ Technical Support.

The resetclocks option must be run in single-user mode and is allowed only with the DBCC statement allocation database. The syntax of resetclocks is:

sp_iqcheckdb 'allocation database resetclocks'
Check Verifies that all database pages can be read for the entire database, main cache, specific index, specific index type, specific table, specific partition, or specific dbspace. If the table is partitioned, then check mode will check the table’s partition allocation bitmaps.

Run in check mode if metadata, null count, or distinct count errors are returned when running a query.

Verify Verifies the contents of non-FP indexes with their corresponding FP indexes for the entire database, main cache, a specific index, a specific index type, specific table, specific partition, or specific dbspace. If the specified target contains all data pages for the FP and corresponding non-FP indexes, then verify mode detects the following inconsistencies:
  • Missing key – a key that exists in the FP but not in the non-FP index.
  • Extra key – a key that exists in the non-FP index but not in the FP index.
  • Missing row – a row that exists in the FP but not in the non-FP index.
  • Extra row – a row that exists in the non-FP index but not in the FP index.
If the specified target contains only a subset of the FP pages, then verify mode can detect only the following inconsistencies:
  • Missing key
  • Missing row

If the target is a partitioned table, then verify mode also verifies that each row in the table or table partition has been assigned to the correct partition.

Run in verify mode if metadata, null count, or distinct count errors are returned when running a query.

Note: sp_iqcheckdb does not check referential integrity or repair referential integrity violations.
Dropleaks When the SAP Sybase IQ server runs in single-node mode, you can use dropleaks mode with either a database or dbspace target to reset the allocation map for the entire database or specified dbspace targets. If the target is a dbspace, then the dropleaks operation must also prevent read-write operations on the named dbspace. All dbspaces in the database or dbspace list must be online.

On a multiplex coordinator node, dropleaks mode also detects leaked blocks, duplicate blocks, or extra blocks across the multiplex.

DBCC Performance:

The execution time of DBCC varies, depending on the size of the database for an entire database check, the number of tables or indexes specified, and the size of the machine. Checking only a subset of the database (that is, only specified tables, indexes, or index types) requires less time than checking an entire database.

The processing time of sp_iqcheckdb dropleaks mode depends on the number of dbspace targets.

This table summarizes the actions and output of the four sp_iqcheckdb modes.

Actions and Output of sp_iqcheckdb Modes
Mode Errors Detected Output Speed
Allocation Allocation errors Allocation statistics only 4TB per hour
Check Allocation errors

Most index errors

All available statistics 60GB per hour
Verify Allocation errors

All index errors

All available statistics 15GB per hour
Dropleaks Allocation errors Allocation statistics only 4TB per hour

Output:

Depending on the execution mode, sp_iqcheckdb output includes summary results, errors, informational statistics, and repair statistics. The output may contain as many as three results sets, if you specify multiple modes in a single session. Error statistics are indicated by asterisks (*****), and appear only if errors are detected.

The output of sp_iqcheckdb is also copied to the SAP Sybase IQ message file .iqmsg. If the DBCC_LOG_PROGRESS option is ON, sp_iqcheckdb sends progress messages to the IQ message file, allowing the user to follow the progress of the DBCC operation as it executes.

Example

Check the allocation for the entire database:

sp_iqcheckdb 'allocation database'

Perform a detailed check on indexes i1, i2, and dbo.t1.i3. If you do not specify a new mode, sp_iqcheckdb applies the same mode to the remaining targets, as shown in the following command:

sp_iqcheckdb 'verify index i1 index i2 index dbo.t1.i3'

You can combine all modes and run multiple checks on a database in a single session. Perform a quick check of partition p1 in table t2, a detailed check of index i1, and allocation checking for the entire database using half of the CPUs:

sp_iqcheckdb 'check table t2 partition p1 verify index i1
allocation database resources 50'

Check all indexes of the type FP in the database:

sp_iqcheckdb 'check indextype FP database'

Verify the FP and HG indexes in the table t1 and the LF indexes in the table t2:

sp_iqcheckdb 'verify indextype FP indextype HG table t1 indextype LF table t2'

Check for LVC cell inconsistencies:

sp_iqcheckdb 'check index EFG2JKL.ASIQ_IDX_T208_C504_FP'
------------------------------------
Index Statistics:
** Inconsistent Index: abcd.EFG2JKL.ASIQ_IDX_T208_C504_FP ****** FP
Indexes Checked: 1
** Unowned LVC Cells: 212 ******

The sp_iqcheckdb LVC cells messages include:

These messages indicate inconsistencies with a VARCHAR, VARBINARY, LONG BINARY (BLOB), or LONG VARCHAR (CLOB) column. Unowned LVC cells represent a small amount of unusable disk space and can safely be ignored. Duplicate and Unallocated LVC cells are serious errors that can be resolved only by dropping the damaged columns.

To drop a damaged column, create a new column from a copy of the old column, then drop the original column and rename the new column to the old column.

Note: LVC is a VARCHAR or VARBINARY column with a width greater than 255. LONG BINARY (BLOB) and LONG VARCHAR (CLOB) also use LVC.

Output Example:

Run sp_iqcheckdb 'allocation database':

===================================================================
DBCC Allocation Mode Report 
===================================================================
   DBCC Status                                    No Errors Detected 
===================================================================
Allocation Summary
=================================================================== 
   Blocks Total                                   25600
   Blocks in Current Version                      5917
   Blocks in All Versions                         5917
   Blocks in Use                                  5917
   % Blocks in Use                                23  
===================================================================
Allocation Statistics
===================================================================
   Marked Logical Blocks                          8320
   Marked Physical Blocks                         5917
   Marked Pages                                   520 
   Blocks in Freelist                             2071196 
   Imaginary Blocks                               2014079 
   Highest PBN in Use                             1049285  
   Total Free Blocks                              19683 
   Usable Free Blocks                             19382
   % Total Space Fragmented                       1 
   % Free Space Fragmented                        1  
   Max Blocks Per Page                            16 
   1  Block Page Count                            165
   3  Block Page Count                            200 
   4  Block Page Count                            1    
   10 Block Page Count                            1 
   16 Block Page Count                            153 
   2  Block Hole Count                            1      
   3  Block Hole Count                            19   
   6  Block Hole Count                            12    
   7  Block Hole Count                            1    
   10 Block Hole Count                            1   
   15 Block Hole Count                            1  
   16 Block Hole Count                            1220 

Partition Summary    
   Database Objects Checked                       2
   Blockmap Identity Count                        2 
   Bitmap Count                                   2   
===================================================================
Connection Statistics
===================================================================
   Sort Records                                   3260 
   Sort Sets                                      2  
=================================================================== 
DBCC Info    
===================================================================
   DBCC Work units Dispatched                     197  
   DBCC Work units Completed                      197  
   DBCC Buffer Quota                              255  
   DBCC Per-Thread Buffer Quota                   255  
   Max Blockmap ID found                          200  
   Max Transaction ID found                       404
Note: The report may indicate leaked space. Leaked space is a block that is allocated according to the database free list (an internal allocation map), but DBCC finds that the block is not part of any database object.