| Oracle FAQ | Your Portal to the Oracle Knowledge Grid | |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: Compare tow schemas
Hi!
I don't remember the original place but here is one. You may want to adapt it to Your needs.
Gints Plivna
undef prex
undef prefx
undef a
undef thisuser
undef b
undef REMOTESCHEMA
undef REMOTEPASSW
undef connstring
undef c
undef todaysdate
variable prefx varchar2(3)
declare
i number ; j number ; k number ;
select count(*) into cnt from user_objects where object_name like
chr(i)||chr(j)||chr(k)||'%';
if cnt = 0 then
:prefx := chr(i)||chr(j)||chr(k);
goto ex;
end if;
PROMPT this schema: &thisuser PROMPT remote schema: &remoteschemaPROMPT
create table &prex.diff_cols1
( TABLE_NAME VARCHAR2(30), COLUMN_NAME VARCHAR2(30), DATA_TYPE VARCHAR2(9), DATA_LENGTH NUMBER, DATA_PRECISION NUMBER, DATA_SCALE NUMBER, NULLABLE VARCHAR2(1), COLUMN_ID NUMBER, DEFAULT_LENGTH NUMBER, DATA_DEFAULT varchar2(2000)); create table &prex.diff_cols2 ( TABLE_NAME VARCHAR2(30), COLUMN_NAME VARCHAR2(30), DATA_TYPE VARCHAR2(9), DATA_LENGTH NUMBER, DATA_PRECISION NUMBER, DATA_SCALE NUMBER, NULLABLE VARCHAR2(1), COLUMN_ID NUMBER, DEFAULT_LENGTH NUMBER, DATA_DEFAULT varchar2(2000));declare
l.TABLE_NAME , l.COLUMN_NAME, l.DATA_TYPE , l.DATA_LENGTH, l.DATA_PRECISION , l.DATA_SCALE , l.NULLABLE, l.COLUMN_ID , l.DEFAULT_LENGTH , l.DATA_DEFAULT
TABLE_NAME VARCHAR2(30), COLUMN_NAME VARCHAR2(30), DATA_TYPE VARCHAR2(9), DATA_LENGTH NUMBER, DATA_PRECISION NUMBER, DATA_SCALE NUMBER, NULLABLE VARCHAR2(1), COLUMN_ID NUMBER, DEFAULT_LENGTH NUMBER, DATA_DEFAULT varchar2(2000));
(c.table_name,c.column_name,c.data_type,c.data_length,
c.DATA_PRECISION, c.DATA_SCALE, c.NULLABLE, c.COLUMN_ID,
c.DEFAULT_LENGTH, c.DATA_DEFAULT);
l.TABLE_NAME , l.COLUMN_NAME, l.DATA_TYPE , l.DATA_LENGTH, l.DATA_PRECISION , l.DATA_SCALE , l.NULLABLE, l.COLUMN_ID , l.DEFAULT_LENGTH , l.DATA_DEFAULT
TABLE_NAME VARCHAR2(30), COLUMN_NAME VARCHAR2(30), DATA_TYPE VARCHAR2(9), DATA_LENGTH NUMBER, DATA_PRECISION NUMBER, DATA_SCALE NUMBER, NULLABLE VARCHAR2(1), COLUMN_ID NUMBER, DEFAULT_LENGTH NUMBER, DATA_DEFAULT varchar2(2000));
(c.table_name,c.column_name,c.data_type,c.data_length,
c.DATA_PRECISION, c.DATA_SCALE, c.NULLABLE, c.COLUMN_ID,
c.DEFAULT_LENGTH, c.DATA_DEFAULT);
l.column_name=r.column_name and l.DATA_DEFAULT != r.DATA_DEFAULT
union
select l.table_name,l.column_name,'DATA_TYPE',l.data_type,r.data_type
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.data_type != r.data_type
union
select l.table_name,l.column_name,'DATA_LENGTH',to_char(l.data_length),
to_char(r.data_length)
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.data_length != r.data_length
union
select l.table_name,l.column_name,'DATA_PRECISION',
to_char(l.DATA_PRECISION),to_char(r.DATA_PRECISION)
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.DATA_PRECISION != r.DATA_PRECISION
union
select l.table_name,l.column_name,'DATA_SCALE',to_char(l.DATA_SCALE),
to_char(r.DATA_SCALE)
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.DATA_SCALE != r.DATA_SCALE
union
select l.table_name,l.column_name,'NULLABLE',l.NULLABLE,r.NULLABLE
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.NULLABLE != r.NULLABLE
union
select l.table_name,l.column_name,'NULLABLE',to_char(l.COLUMN_ID),
to_char(r.COLUMN_ID)
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.COLUMN_ID != r.COLUMN_ID
union
select l.table_name,l.column_name,'NULLABLE',to_char(l.DEFAULT_LENGTH),
to_char(r.DEFAULT_LENGTH)
from &prex.diff_cols1 l, &prex.diff_cols2 r
where l.table_name=r.table_name and
l.column_name=r.column_name and l.DEFAULT_LENGTH != r.DEFAULT_LENGTH
order by 1,2
/
create table &prex.ind1 as
select table_name,index_name from user_indexes@&prex.lnk
where table_name in
(select table_name from &prex.common_tables)
minus
select table_name,index_name from user_indexes
where table_name in
(select table_name from &prex.common_tables);
PROMPT
PROMPT
PROMPT
q.index_name=a.index_name and a.index_name=b.index_name and a.column_position=b.column_position(+) and a.column_name != b.column_name(+)
q.index_name=a.index_name and a.index_name=b.index_name and a.column_position=b.column_position(+) and a.column_name != b.column_name(+)
a.table_name = b.table_name and a.constraint_name=b.constraint_name and a.constraint_type !=b.constraint_type;
from user_cons_columns a, &prex.comcons b
where a.constraint_name=b.constraint_name
intersect
select a.constraint_name,a.position,a.column_name,b.constraint_type
from user_cons_columns@&prex.lnk a, &prex.comcons b
where a.constraint_name=b.constraint_name
);
i binary_integer;
begin
for c in c1 loop
dbms_output.put_line('COLUMN USAGE DIFFERENCE FOR '||c.constraint_type||
' CONSTRAINT '||c.constraint_name);
dbms_output.put_line('. Local columns:');
i:=1;
for c2 in (select column_name col
from user_cons_columns
where constraint_name=c.constraint_name order by position)
loop
dbms_output.put_line('. '||c2.col);
end loop;
from user_cons_columns@&prex.lnk
where constraint_name=c.constraint_name
)
loop
dbms_output.put_line('. '||c3.col);
end loop;
cons varchar2(50); tab1 varchar2(50); tab2 varchar2(50);
dbms_output.put_line('Check constraint '||c.constraint_name||
' defined differently!');
dbms_output.put_line('. Local definition:');
dbms_output.put_line('. '||search1);
dbms_output.put_line('. Remote definition:');
dbms_output.put_line('. '||search2);
end if;
desc1 varchar2(2000); body1 varchar2(32000); type2 varchar2(16);
-------------------------------------------------'||
'-----------------------');
pr_head := TRUE;
dbms_output.put_line(' ');
dbms_output.put_line('DEFINED ON DIFFERENT TABLES!');
dbms_output.put_line('. This table_name : '||table1);
dbms_output.put_line('. Remote table_name: '||table2);
end if;
dbms_output.put_line('T R I G G E R : '||nam1);
dbms_output.put_line('
-------------------------------------------------'||
'-----------------------');
pr_head := TRUE;
dbms_output.put_line(' ');
dbms_output.put_line('DEFINED FOR DIFFERENT EVENTS!');
dbms_output.put_line('. This event: '||event1);
dbms_output.put_line('. Remote event: '||event2);
end if;
dbms_output.put_line('T R I G G E R : '||nam1);
dbms_output.put_line('
-------------------------------------------------'||
'-----------------------');
pr_head := TRUE;
dbms_output.put_line(' ');
dbms_output.put_line('DIFFERENT TYPES!');
dbms_output.put_line('. This type: '||type1);
dbms_output.put_line('. Remote: '||type2);
end if;
dbms_output.put_line('T R I G G E R : '||nam1);
dbms_output.put_line('
-------------------------------------------------'||
'-----------------------');
pr_head := TRUE;
dbms_output.put_line(' ');
dbms_output.put_line('DIFFERENT REFERENCES!');
dbms_output.put_line('. This ref: '||ref1);
dbms_output.put_line('. Remote: '||ref2);
end if;
dbms_output.put_line('T R I G G E R : '||nam1);
dbms_output.put_line('
-------------------------------------------------'||
'-----------------------');
pr_head := TRUE;
dbms_output.put_line('DIFFERENT WHEN CLAUSES!');
dbms_output.put_line('. Local when_clause:');
dbms_output.put_line(when1);
dbms_output.put_line('. Remote when_clause: ');
dbms_output.put_line(when2);
dbms_output.put_line(' ');
dbms_output.put_line('DIFFERENT STATUS!');
dbms_output.put_line('. Local status: '||status1);
dbms_output.put_line('. Remote status: '||status2);
end if;
dbms_output.put_line(' ');
dbms_output.put_line('DIFFERENT DESCRIPTIONS!');
dbms_output.put_line('Local definition: ');
dbms_output.put_line(desc1);
dbms_output.put_line('Remote definition: ');
dbms_output.put_line(desc2);
dbms_output.put_line(' ');
end if;
exception when NO_DATA_FOUND then null;
when others then raise_application_error(-20010,SQLERRM);
end;
end loop;
end;
/
PROMPT
PROMPT
PROMPT
from user_source a, &prex.comcod b
where a.name=b.name union
select a.name,a.type,a.line,a.text
from user_source@&prex.lnk a, &prex.comcod b
where a.name=b.name
minus
(select a.name,a.type,a.line,a.text
from user_source a, &prex.comcod b
where a.name=b.name
intersect
select a.name,a.type,a.line,a.text
from user_source@&prex.lnk a, &prex.comcod b
where a.name=b.name )) q;
PROMPT
PROMPT
PROMPT
' is not defined identically! |');
dbms_output.put_line(lpad('-',35+length(c.view_name),'-'));
dbms_output.put_line(' ');
dbms_output.put_line(substr(def1,i,255));
i:=i+255;
dbms_output.put_line(substr(def2,i,255));
i:=i+255;
drop table &prex.comcod; drop table &prex.diff_cols1; drop table &prex.diff_cols2; drop table &prex.common_tables; drop table &prex.common_views; drop table &prex.ind; drop table &prex.ind1; drop table &prex.ind2; drop table &prex.comcons;
PROMPT ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~PROMPT Finished! Result stored in file dbdiff.lst
PROMPT ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: INET: G.Plivna_at_itsystems.lv Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).Received on Thu Apr 05 2001 - 02:51:49 CDT
![]() |
![]() |