April 4, 2011 at 11:11 am
Hey all,
I have an issue where some of the databases I'm administering have a table where the identity column is incorrectly set for replication. I want to know if there is a way I can check the "not for replication" status for a field, so that I don't have to recreate the table if I don't have to.
I know there are easy ways to check this using more recent versions of SQL, but is there anyway to do this using SQL 2000? I couldn't find a way to access this property using the Properties dialog boxes in Query Analyzer or Enterprise Manager. I would greatly appreciate any help that anyone can give.
April 15, 2011 at 10:52 am
Use this SQL 2005+ query:
SELECT OBJECT_NAME(object_id) AS TableName ,
name AS ColumnName ,
TYPE_NAME(system_type_id) AS DataType ,
max_length ,
is_nullable ,
is_replicated
FROM sys.columns
For SQL Server 2000 use this code
SELECT COLUMNPROPERTY( OBJECT_ID('SchemaName.TableName'),'ColumnName','IsIdNotForRepl')
QUIGROUP- Need a Certified experienced DBA for a project or troubleshooting? Need help with programming, database recovery, performance tuning, ETL, SSRS or developing new databases? Contact us.. 1-786-273-9809
October 13, 2011 at 11:45 am
Thanks for the reply. When you fill in the relevant names for tablename and id name, that SQL 2000 statement works.
I also found a way to check this in the GUI.
--Go to Enterprise Manager.
--Expand Root, Microsoft SQL Servers, SQL Server Group, [instance name], Databases, [database name], Tables
--Right-click on the table name, choose "Design Table"
--With the ID column highlighted, the panel below the design table cells will contain whether or not the table is for replication under the Identity box. For example, it might list Yes (Not For Replication)
That doesn't seem like a very intuitive place to look compared to the properties of the table, but there you go. I hope this is of help to someone.
August 13, 2014 at 9:09 am
I have been currently using the following script to check if the identity column in my tables exist, and if so, is not for replication.
hope it helps
marcelo
SELECT OBJECT_SCHEMA_NAME(p.object_id) AS [Schema]
, OBJECT_NAME(p.object_id) AS [Table]
, i.name AS [Index]
, p.partition_number
, p.rows AS [Row Count]
, i.type_desc AS [Index Type]
,K.increment_value as IncrementValue
,K.last_value as LastValue
,K.seed_value as SeedValue
,k.is_nullable
,k.is_identity
,k.is_filestream
,k.is_replicated
,k.is_not_for_replication
FROM sys.partitions p
INNER JOIN sys.indexes i
ON p.object_id = i.object_id
AND p.index_id = i.index_id
INNER JOIN SYS.TABLES S
ON S.object_id = P.object_id
LEFT OUTER JOIN sys.identity_columns K
ON P.object_id = K.object_id
WHERE i.index_id < 2 -- GET ONLY THE CLUSTERED INDEXES - IF EXISTS ANY
ORDER BY [Schema], [Table], [Index]
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply