Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


An Identity Crisis


An Identity Crisis

Author
Message
G.R.Prithiviraj Kulasingham
G.R.Prithiviraj Kulasingham
SSC-Addicted
SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)

Group: General Forum Members
Points: 427 Visits: 367

I mentioned 3 points... Unfortunately all negative points:

1. The crisis is nothing to do with Identity. It is regarding DB design. I believe all agree on that.

2. This is about the various ways you can identify identity values. Unless we have a performance issue or do are planning to modify the system entries, using system functions is the best way to retrieve the identity value. This point leads to the third argument.

3. I am sure Performance is not an issue in identifying the identity column, and current value. Is the author planning to change the values? Yes. If he is going to manipulate system tables, those information are useful. Otherwise what’s the point of accessing system tables? That is my final argument. How these system table values helped him to change the data type. Unless he specifies that, that part is not useful.

I am sorry, The article isn't useful to me.



Cheers,
Prithiviraj Kulasingham

http://preethiviraj.blogspot.com/
Michael Fleming
Michael Fleming
SSC Rookie
SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)SSC Rookie (32 reputation)

Group: General Forum Members
Points: 32 Visits: 1

The is also a SQLServer function called COLUMNPROPERTY that you can use to find Identity colums. Try the following :

Select O.name as [Table],
C.name as [Column],
T.name as [Type]
from sysobjects O
join syscolumns C on (C.id=O.id)
join systypes T on (T.xtype=C.xtype)
where COLUMNPROPERTY(O.id, C.name, 'IsIdentity')=1
and O.type = 'U'





cs_troyk
cs_troyk
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1529 Visits: 965

It's true that the problem can crop up on non-identity columns. I acknowledged that in a previous post on this thread.

However, I think most autoincrement solutions use the Identity property as a means of implementation. Therefore, the problem of an autoincrementing column overflowing the datatype's boundaries is most likely to occur on an Identity column.

I have completed and submitted a script which will grab the maximum value for all integer columns on user tables within a database. Once the script has undergone the sqlservercentral.com vetting process, I'll post the link.

TroyK





G.R.Prithiviraj Kulasingham
G.R.Prithiviraj Kulasingham
SSC-Addicted
SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)SSC-Addicted (427 reputation)

Group: General Forum Members
Points: 427 Visits: 367

My apologies... Just a few minutes back I found another area where we need to access system tables: to identify current identity values on linked server. you article is usefull in that ara, as most of the system functions won't work across servers.



Cheers,
Prithiviraj Kulasingham

http://preethiviraj.blogspot.com/
Jane Matheson-154829
Jane Matheson-154829
SSC-Addicted
SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)SSC-Addicted (442 reputation)

Group: General Forum Members
Points: 442 Visits: 185

The following way to find indentities is returning invalid results:


SELECT table_name, column_name, ordinal_position orgPostion, data_type
FROM INFORMATION_SCHEMA.COLUMNS (NOLOCK)
where COLUMNPROPERTY (OBJECT_ID(Table_Name),Column_Name,'IsIdentity') = 1
order by table_name, column_name

It returns an integer field from a view as an identity. The source of this view is a table in another database. The base table does not have an identity defined. The field is an "int not null."

You will need to filter out views.


Frank Kalis
Frank Kalis
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5971 Visits: 289

... and if that still isn't enough, and you know in advance that you need to keep a row for almost every single grain of sand in the Sahara, you can do something like:

create table decimal_t
(
col1 decimal(38,0) identity(-99999999999999999999999999999999999999, 1)
)



--
Frank Kalis
Microsoft SQL Server MVP
Webmaster: http://www.insidesql.org/blogs
My blog: http://www.insidesql.org/blogs/frankkalis/
Adam Machanic
Adam Machanic
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1141 Visits: 714
And if you need even MORE, you can use the large number libraries posted on my blog

--
Adam Machanic
SQL Server MVP
SQLblog.com: THE SQL Server Blog Spot on the Web
Frank Kalis
Frank Kalis
SSCertifiable
SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)SSCertifiable (6K reputation)

Group: General Forum Members
Points: 5971 Visits: 289

Haha, for qualifying this as a shameless plug, you forgot to post the URL.



--
Frank Kalis
Microsoft SQL Server MVP
Webmaster: http://www.insidesql.org/blogs
My blog: http://www.insidesql.org/blogs/frankkalis/
Adam Machanic
Adam Machanic
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1141 Visits: 714
It wasn't a shameless plug -- I would hope that no one would ever actually use it!

--
Adam Machanic
SQL Server MVP
SQLblog.com: THE SQL Server Blog Spot on the Web
Peter DeBetta
Peter DeBetta
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 49

A better version of the code from my previous post

SELECT T.TABLE_SCHEMA, T.TABLE_NAME, C.COLUMN_NAME, C.DATA_TYPE,
IDENT_CURRENT(T.TABLE_SCHEMA + '.' + T.TABLE_NAME) [CURRENT_IDENTITY_VALUE]
FROM INFORMATION_SCHEMA.TABLES AS T (NOLOCK)
INNER JOIN INFORMATION_SCHEMA.COLUMNS AS C (NOLOCK)
ON C.TABLE_SCHEMA = T.TABLE_SCHEMA AND C.TABLE_NAME = T.TABLE_NAME
WHERE T.TABLE_TYPE = 'BASE TABLE'
AND COLUMNPROPERTY (OBJECT_ID(T.TABLE_SCHEMA + '.' + T.TABLE_NAME), C.COLUMN_NAME, 'IsIdentity') = 1
ORDER BY T.TABLE_SCHEMA, T.TABLE_NAME, C.COLUMN_NAME

--Peter


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