SQLServerCentral Article

An Identity Crisis

,

An IDENTITY Crisis

Introduction

Recently, I did some troubleshooting and cleanup with a company on their mission-critical backend database server. One of the main processing tables was defined with an IDENTITY column, which had overflowed the upper boundary of the integer datatype within about 8 months of its implementation. Clearly, the table is central to a lot of processing! The column was only used as an organizing ID (no FK's, etc.) which, thankfully, made cleanup easier. I won't go into the details of the cleanup operation other than to say that the column datatype is now a bigint, and the table should now have no problems for the next 6 to 9 Billion years.

So what else...?

Once the dust settled, the next step was to double-check for any other tables that had a similar time bomb waiting to go off. What we needed was a way to find all of the IDENTITY columns in a given database and check their current values and datatypes. My first instinct was to "do the right thing" and use the INFORMATION_SCHEMA views to get the information (Figure 1). The COLUMNS view, however, doesn't express whether a column has the IDENTITY property. I couldn't find any indication that any of the other views had this information either. I'm no ANSI standards expert, but my assumption is that the reason for the lack of support in the views is that they're compliant with the SQL-92 version of the standard, and "autonumber" column support wasn't added until the SQL-99 version.

Next step... cheat!

Since I knew that the sp_help system proc displays information on the IDENTITY column, I decided to look through the code to see how our friends at Microsoft determine this. Here's the relevant snippet:

...
select @colname = name from syscolumns where id = @objid
and colstat & 1 = 1
...

Now that I had a way to find the IDENTITY columns, I was able to construct a query to show me the table name, column name, datatype, and current value (using IDENT_CURRENT):

SELECT o.name [tableName], c.name [columnName], TYPE_NAME(c.xtype) [dataType], IDENT_CURRENT(o.name) [currentVal]
FROM syscolumns c
INNER JOIN sysobjects o
ON c.id = o.id
WHERE o.xtype = 'U' -- User table
  AND c.colstat & 1 = 1

You say tomato, I say...

Some digging around on the SQLServerCentral.com website turned up some additional information on keeping IDENTITY columns healthy. I found the following article and scripts:

http://www.sqlservercentral.com/columnists/sjones/identityreset.asp
http://www.sqlservercentral.com/scripts/contributions/65.asp
http://www.sqlservercentral.com/scripts/contributions/1279.asp

I thought it would be interesting to catalog the various ways of determining if a column is an IDENTITY column. Here's what I found (and it wouldn't surprise me if I missed some):

syscolumns.colstat & 1 = 1

-- computed column, partly based on colstat... syscolumns.status & 128 = 128
-- suspicious, but seems to work... syscolumns.autoval IS NOT NULL
-- computed as convert(varchar(255),autoval) syscolumns.printfmt IS NOT NULL

Conclusion

Now that we have a script which will give us the values for all of our IDENTITY columns, we can periodically log the values to an audit table and project when the datatype might run out of "room" to represent the values. Of course, if one is dealing with an environment where IDENTITY columns are used prolifically, it makes sense to concentrate only on the most active tables--presumably those with the highest values. Using this technique, we did discover another table with an integer IDENTITY column that's already used up nearly 1/3 of the values available to an integer. We can now deal with this before it becomes a problem.

Troy Ketsdever

Silver Creek Consulting, LLC

© 2005

Rate

5 (4)

You rated this post out of 5. Change rating

Share

Share

Rate

5 (4)

You rated this post out of 5. Change rating