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


How to find out the identity coloumn of a table.


How to find out the identity coloumn of a table.

Author
Message
madhavi guthula
madhavi guthula
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 1

Hi,

I want to drop the identity property of a coloumn in a table.But i dont know the column which has the identity property.

so please let me know How to find out the idntity column and how to drop the identity property of that coloumn.

ThanQ.


SwePeso
SwePeso
SSCrazy
SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)SSCrazy (2.5K reputation)

Group: General Forum Members
Points: 2469 Visits: 3431
SELECT identitycol FROM WhatEverTable WHERE 1 = 0


N 56°04'39.16"
E 12°55'05.25"
madhavi guthula
madhavi guthula
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 1

ThanQ for the solution.

But i want to drop the identity property of that coloumn.

How can i do it in TSQL. please let me know.


GARCIA
GARCIA
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 46

Hi,

hope it will help you

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

declare @TblName sysname

set @tblName = 'Your table name'

-- show identity col name
select syscolumns.name from sysobjects
inner join syscolumns on sysobjects.id = syscolumns.id
where sysobjects.name = @tblName and syscolumns.status = 0x80

-- show identity constraint name
select sysobjconstraint.name from sysobjects
inner join sysconstraints on sysobjects.id = sysconstraints.id
left outer join sysobjects sysobjconstraint on sysconstraints.constid = sysobjconstraint.id
where sysobjects.name = @tblName and sysobjconstraint.xtype = 'PK'

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

use the resultset into ALTER TABLE DROP CONSTRAINTS but be carefull with FK, for detecting FK take a look at sysforeignkeys table


Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14957 Visits: 38958

there's a difference between a primary key, which technically can span multiple columns, and a column that has the identity function on it to auto generate the next value of the table;

there can be only one column in a table where the autoval is not null(which identifies it as the column that was created with identity)

with both the drop constraint for the PK and the alter table to remove the identity(), i think that's the tools you need.

here i'm expanding Gracia's example to include that as well:

declare @TblName sysname

set @tblName = 'GMACT'

-- show identity col name
select
'ALTER TABLE '
+ @tblName
+ ' ALTER COLUMN '
+ UPPER(syscolumns.name)
+ SPACE(2)
+ UPPER(TYPE_NAME(syscolumns.xtype))
--this is for the original definition
--+ SPACE(12 - LEN(TYPE_NAME(syscolumns.xtype))) + CASE WHEN syscolumns.autoval IS NULL THEN ' ' ELSE ' IDENTITY(1,1)' END
+ SPACE(2) + CASE WHEN syscolumns.isnullable=0 THEN ' NOT NULL' ELSE ' NULL' END AS ORIGINAL_DEFINITION,
syscolumns.name from sysobjects
inner join syscolumns on sysobjects.id = syscolumns.id
where sysobjects.name = @tblName and autoval is not null

-- show identity constraint name
select 'ALTER TABLE ' + @tblName + ' DROP CONSTRAINT ' + sysobjconstraint.name AS DROP_STATEMENT,sysobjconstraint.name from sysobjects
inner join sysconstraints on sysobjects.id = sysconstraints.id
left outer join sysobjects sysobjconstraint on sysconstraints.constid = sysobjconstraint.id
where sysobjects.name = @tblName and sysobjconstraint.xtype = 'PK'

--select * from syscolumns where autoval is not null

results:

ORIGINAL_DEFINITION
----------------------------------------------------------
ALTER TABLE GMACT ALTER COLUMN ACTTBLKEY INT NOT NULL

DROP_STATEMENT
----------------------------------------------------------
ALTER TABLE GMACT DROP CONSTRAINT PK__GMACT__1E05700A



Lowell

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

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