May 10, 2006 at 4:51 am
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.
May 10, 2006 at 5:12 am
SELECT identitycol FROM WhatEverTable WHERE 1 = 0
N 56°04'39.16"
E 12°55'05.25"
May 10, 2006 at 5:59 am
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.
May 11, 2006 at 5:28 am
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
May 11, 2006 at 6:36 am
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
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply