SQLServerCentral Article

How to Fix Inconsistent Metadata Errors

,

Why does changing a table on a SQL Server 7.0 server cause "OLE DB provider 'SQLOLEDB'

supplied inconsistent metadata. An extra column was supplied during execution

that was not found at compile time." to occur when query the table from a SQL

Server 2000 server via link to other.

BASIC UNDERSTANDING OF THE PROBLEM:

OK here is what I discovered.  In SQL Server 7.0 when a column is

deleted, the syscolumns table keeps the original ordinal position listed instead

of adjusting to what the table looks like now.

For example, table 1:

ColName OrdPos

-----------   ---

Col1          1

Col2          2

Col3          3

Col4          4

Col5          5

Col6          6

In SQL Server 7.0 when you remove Col3, Col4 a result of Ordinal Position in

the syscolumns table would look like this:

ColName OrdPos

-----------  ---

Col1         1

Col2         2

Col5         5

Col6         6

SQL Server 2000 though will actually reset the values and the output looks

like this

ColName OrdPos

-----------  ---

Col1         1

Col2         2

Col5         3

Col6         4

OK when you link from SQL Server 2000 to SQL Server 7.0 the link will run

several request one being

sp_columns_rowset N'yourTblNamehere', N'dbo', NULL

and it apparently reads the ORDINAL POSITION column which when is first built

is in order by when you delete items it is no longer with SQL 7 so it outputs

THE ERROR MESSAGE:

Server: Msg 7353, Level 16, State 1, Line 1

OLE DB provider 'SQLOLEDB' supplied inconsistent metadata. An extra column

was supplied during execution that was not found at compile time.

WHAT I DID:

(note: testing was done on all versions of SQL Server 7.0 with each SP level

thru 3)

First I opened Profiler and connected to the remote server to watch the calls

being made and looked at the items it ran, testing each until I saw

sp_columns_rowset as the only column related item. Then running I noticed the

ORDINAL POSITION output was not consecutive which made me curious so I deleted

and re-added the table with the final version the table was in and ran the

process again. This time the ORDINAL POSITION output was consecutive and when I

ran my query from the other server it worked fine. So I removed another column

from before then end of the table and ran query again and got output again. Then

I went back and look at the ORDINAL POSITION output of sp_columns_rowset and

again not consecutive. So I decided to try under SQL 2000, and noticed that

whenever I changed the columns that the ORDINAL POSITION reset and remained

consecutive. Now I decided must be that output for is the cause of the error and

decided to manually change the values in the syscolumns table myself. Ran my

remote query again, which ran without error.

OK so I know the problem and potential how to fix, but the fix is a bit of a

headache. That is where the following came from. I decided the best way to quick

fix was to build a process I can run to handle it quickly for me. To use just

load into master (as you will probably use it often to clean

up) and run like so:

USE YourDBHere

GO

sp_FixColOrder YourTableNameHere

GO

OR

YourDBHere..sp_FixColOrder YourTableNameHere

Anyway here is the fix code and I will send this entire message to Microsoft

to follow up on. Hopefully they will provide a better fix for this in SP4 if I

can get in soon enough.

THE PROCEDURE:

-------------------------------------Procedure Begins

Here----------------------------------------

/*

* Procedure Name: sp_FixColOrder

* Full Name: Fix Column Order

* Created: 2/21/2002

* Created By: James Travis

* Desc: Fix column order listing in syscolumns table for specified table.

* Notes: For use with SQL 7 only, not tested elsewhere. Procedure makes use of

* changing value in system table which can cause issues and even though

* I have tested I make no guarantees on the effects of this procedure.

*/

CREATE PROCEDURE sp_FixColOrder

@table sysname

AS

DECLARE @SQLState VARCHAR(2000)

--Configure server to allow ad hoc updates to system tables

EXEC master.dbo.sp_configure 'allow updates', '1' RECONFIGURE WITH OVERRIDE

/*Build string to update object, the only reason I build a string is the allow

updates exec does not allow straight SQL to occurr.*/

SET @SQLState = 'UPDATE

syscolumns

SET

colid = TruePos,

colorder = TruePos

FROM

syscolumns

INNER JOIN

(SELECT

[name],[id],

colorder, (SELECT COUNT(*) + 1 FROM syscolumns ic WHERE ic.colorder < c.colorder

AND ic.[id] = c.[id]) as TruePos

FROM syscolumns c WHERE [id] = OBJECT_ID(''' + @table + ''')

) AS CalcVals ON syscolumns.[name] = CalcVals.[name] AND syscolumns.[id] =

CalcVals.[id] AND

syscolumns.colorder = CalcVals.colorder'

EXEC (@SQLState)

--Configure server to disallow ad hoc updates to system tables

EXEC master.dbo.sp_configure 'allow updates', '0' RECONFIGURE WITH OVERRIDE

Rate

5 (1)

You rated this post out of 5. Change rating

Share

Share

Rate

5 (1)

You rated this post out of 5. Change rating