SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2008 Forums
 Other SQL Server 2008 Topics
 AutoNumber PKey fields
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

stackerman
Starting Member

USA
1 Posts

Posted - 08/20/2014 :  14:38:34  Show Profile  Reply with Quote
Ok - so admittedly I am no DBA - just a SysAdmin/Security guy. I do know enough to realize that we had issues recently with SQL Replication that were due to AutoNumber fields being used as the PKEY and inconsistencies in the relationships afterwards due to it.

I know that we COULD choose the not for repl option on these OR create some type of GUID field, etc (that will be up to the dev guys). For now I am curious though if there is a way to assess how large a task this will be? What I really think I am looking for is a query that will audit/list any tables that have an AUTONUMBER field used as the PKEY...

Is there a simple query for this?

tkizer
Almighty SQL Goddess

USA
37134 Posts

Posted - 08/20/2014 :  14:48:47  Show Profile  Visit tkizer's Homepage  Reply with Quote
Here you go:
select object_name(object_id) as TableName, name as ColumnName
from sys.columns
where is_identity = 1
order by 1

Tara Kizer
SQL Server MVP since 2007
http://weblogs.sqlteam.com/tarad/
Go to Top of Page

tkizer
Almighty SQL Goddess

USA
37134 Posts

Posted - 08/20/2014 :  14:49:57  Show Profile  Visit tkizer's Homepage  Reply with Quote
As a DBA, I would recommend using the NOT FOR REPLICATION option instead of a GUID column. There are challenges with GUIDs. Too big of a topic here, but it's something that needs to be researched and designed properly.

Tara Kizer
SQL Server MVP since 2007
http://weblogs.sqlteam.com/tarad/
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000