SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to check "not for replication" status using T-SQL or GUI in SQL 2000


How to check "not for replication" status using T-SQL or GUI in SQL 2000

Author
Message
SQLUserC
SQLUserC
Mr or Mrs. 500
Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)

Group: General Forum Members
Points: 521 Visits: 328
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.
Ysaias Portes-QUI Group
Ysaias Portes-QUI Group
Old Hand
Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)Old Hand (395 reputation)

Group: General Forum Members
Points: 395 Visits: 347
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
SQLUserC
SQLUserC
Mr or Mrs. 500
Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)Mr or Mrs. 500 (521 reputation)

Group: General Forum Members
Points: 521 Visits: 328
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.
marcelo miorelli
marcelo miorelli
SSC-Enthusiastic
SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)SSC-Enthusiastic (129 reputation)

Group: General Forum Members
Points: 129 Visits: 407
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]
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search