Gap sequence of column_id

  • select * from sys.columns where object_id = object_id('tablename')

    This query returns all the columns in the table, however, the column id in between is breaking the sequence. For example after column_id 26, 28 appears but 27 is missing. However the column names are correct and in correct order.

    This is causing issues when performing change manager operation.

    Does anyone has any idea, how this can be fixed?

    Thanks

    Swarndeep

    http://talksql.blogspot.com

  • if you add a drop columns from a table, the column_id is dropped with it; then when you add additional columns, the next column_id is used.

    so if you drop column 4 in a 7 column table, and add another, column_id4 is lost...columns 5 thru 7 do not shift over.

    perfectly normal to see gaps in the column_id; that's by design.

    if you have another process that is counting from 0 to max(column_id), you'd want to change it to use something like a For Each Column in ColumnCollection.

    the only other alternative is to rebuild the tables; i'd recommend using the SSMS GUI, as it handles all the heavy lifting behind the scene...identifying all constraints/foreign keys/defaults/etc, dropping em building new table,dropping old table,renaming new, re-adding all the constraints back.

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Thanks for reply with explanation. I will contact technical support of change manager (DBGhost), which works in this way and there is nothing wrong with tables.

    Swarndeep

    http://talksql.blogspot.com

  • here's a quickie SQL to find tables with "gaps" in the column_id sequence:

    select distinct object_name(object_id) As TableWithGaps

    from (

    select * ,

    row_number() OVER(partition by object_id order by column_id) As RW

    from sys.columns ) X

    where RW <> column_id

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Thanks

    Swarndeep

    http://talksql.blogspot.com

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

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