Skip to Main Content
  • Questions
  • Generate alter table statement with existing constraints in all_constarints

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, partha.

Asked: June 26, 2001 - 10:23 am UTC

Last updated: April 18, 2002 - 8:22 am UTC

Version: 8.1.6

Viewed 1000+ times

You Asked

I want's to Generate alter table statement with existing constraints in all_cons_columns and all_constraints.

Can you please suggest me how do i correct the following statement

SELECT 'ALTER TABLE' ||' '||A.TABLE_NAME||' '||'ADD ( CONSTRAINT'||' '||A.CONSTRAINT_NAME||
' '||
DECODE(B.CONSTRAINT_TYPE,'P','PRIMARY KEY','R','REFERENCES','U','UNIQUE','C','CHEQUE')||
' ('||A.COLUMN_NAME||' )) ;'
FROM ALL_CONS_COLUMNS A,ALL_CONSTRAINTS B
WHERE B.OWNER = 'BISS01' AND
A.OWNER = B.OWNER AND
A.CONSTRAINT_NAME = B.CONSTRAINT_NAME AND
A.TABLE_NAME = B.TABLE_NAME;

Thanks in Advance

Partha

and Tom said...

Here is an example of how to approach this. The following query will, when given a PARENT table name, produce all of the foreign key constraints for its children tables.


column fkey format a80 word_wrapped
select
'alter table "' || child_tname || '"' || chr(10) ||
'add constraint "' || child_cons_name || '"' || chr(10) ||
'foreign key ( ' || child_columns || ' ) ' || chr(10) ||
'references "' || parent_tname || '" ( ' || parent_columns || ');' fkey
from
( select a.table_name child_tname, a.constraint_name child_cons_name,
b.r_constraint_name parent_cons_name,
max(decode(position, 1, '"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 2,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 3,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 4,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 5,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 6,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 7,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 8,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 9,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,10,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,11,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,12,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,13,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,14,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,15,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,16,', '||'"'||
substr(column_name,1,30)||'"',NULL))
child_columns
from user_cons_columns a, user_constraints b
where a.constraint_name = b.constraint_name
and b.constraint_type = 'R'
group by a.table_name, a.constraint_name, b.r_constraint_name ) child,
( select a.constraint_name parent_cons_name, a.table_name parent_tname,
max(decode(position, 1, '"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 2,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 3,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 4,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 5,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 6,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 7,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 8,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position, 9,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,10,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,11,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,12,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,13,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,14,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,15,', '||'"'||
substr(column_name,1,30)||'"',NULL)) ||
max(decode(position,16,', '||'"'||
substr(column_name,1,30)||'"',NULL))
parent_columns
from user_cons_columns a, user_constraints b
where a.constraint_name = b.constraint_name
and b.constraint_type in ( 'P', 'U' )
group by a.table_name, a.constraint_name ) parent
where child.parent_cons_name = parent.parent_cons_name
and parent.parent_tname = upper('&1')
/

Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Generate alter table add Foreign key Constraints table

Partha, June 26, 2001 - 11:13 am UTC

It is very useful script for Datawarehouses

Original question not answered

Kulguru, April 18, 2002 - 12:38 am UTC

Tom, I think the person posting the question , also wanted the primary key constraints along with the foreign i.e. for the given table you should produce the primary , and then all the foreign keys in all the other tables referencing this parent table.

Dont you think so.

Tom Kyte
April 18, 2002 - 8:22 am UTC

And, if given the example, they cannot figure out how to get the primary keys -- they should be in another line of work perhaps.


I did the hard one, you can do the easy one. Getting the primary key is child's play compared to generating the fkey like that.

Take the ideas I have, learn how they work, apply them to new problems.