├── AllineaSequence1.sql
├── AllineaSequence2.sql
├── Apex.sql
├── Autovalid_all_schema.sql
├── COPYING
├── GenSovFK.sql
├── KION.sql
├── Official Scripts
├── Data Check
│ └── check_date.sql
├── Instance Check
│ ├── _check.sql
│ ├── _giusti_locks.sql
│ ├── _io.sql
│ ├── _locks.SQL
│ ├── _processi.sql
│ ├── _rollback_usage.sql
│ ├── _show_dead.SQL
│ ├── _table_locks.sql
│ ├── _top_cpu_sessions.sql
│ ├── datafile_timestamp.sql
│ ├── dbcheck.sql
│ ├── free_space.sql
│ └── who.sql
├── Object Check
│ ├── fk_splitted.sql
│ ├── index_not_used.sql
│ └── notnull_without_default.sql
├── Object management
│ ├── AutoValid.sql
│ ├── Control.sql
│ ├── CreaControlFile.sql
│ ├── CreaSnap.sql
│ ├── DelTabs.SQL
│ ├── DisTrig.sql
│ ├── EnaCons.sql
│ ├── FKList.sql
│ ├── FKListTo.SQL
│ ├── FKUpdateField.sql
│ ├── FkListFrom.sql
│ ├── GenFix.sql
│ ├── GenFix2.sql
│ ├── ShowInvalid.sql
│ ├── TruncTabs.SQL
│ ├── _DisCons.sql
│ ├── dropallfk.sql
│ ├── enatrig.sql
│ ├── fk_splitted.sql
│ ├── grant_select_to_public.sql
│ ├── granttoall.sql
│ ├── mydesc.sql
│ ├── proc_autovalid.sql
│ ├── revGrants.sql
│ ├── revTablespaces.sql
│ └── u_tab_sqlldr_ctl.sql
├── Others
│ ├── CreaUte.sql
│ ├── catexp9.sql
│ ├── dropsyn.SQL
│ └── dropview.SQL
├── Reverse engeenering
│ └── CrIndex.sql
├── Tuning
│ ├── SGA.sql
│ ├── TuneBuf2.sql
│ ├── Tuning.sql
│ ├── latches.sql
│ ├── library_cache.sql
│ ├── recreating_redolog.sql
│ └── redo_log.sql
└── Utils
│ └── hextodec.sql
├── Script
├── Custom
│ └── _testfklocks.sql
├── To Verify
│ ├── CrTable.sql
│ ├── CrTrigger.sql
│ ├── CrView.sql
│ ├── Indice.htm
│ ├── ListTrigger.sql
│ ├── ListView.sql
│ ├── RedirSyn.sql
│ ├── TFkList.sql
│ ├── TRenColumn.sql
│ ├── TReorgTb.sql
│ ├── TRevEngInfo.sql
│ ├── Tools
│ │ ├── Can one monitor how fast a table is imported.sql
│ │ ├── New_sql
│ │ │ ├── allobj.sql
│ │ │ ├── db_revw5.sql
│ │ │ ├── lock.sql
│ │ │ └── whoami.sql
│ │ ├── Rilascio
│ │ │ ├── ListPackage.sql
│ │ │ ├── ListProc.sql
│ │ │ ├── ListTrigger.sql
│ │ │ ├── ListView.sql
│ │ │ ├── START_REV.sql
│ │ │ └── _ListFunc.sql
│ │ ├── Teo
│ │ │ ├── GenSql.sql
│ │ │ ├── GenSql.txt
│ │ │ ├── ListCheck.sql
│ │ │ ├── Locks.sql
│ │ │ ├── Master.sql
│ │ │ ├── MoveIndexes.sql
│ │ │ ├── MoveIndexes.txt
│ │ │ ├── OBJDIFF.SQL
│ │ │ ├── RecRefCons.sql
│ │ │ ├── TABDIFF.SQL
│ │ │ ├── TModiUser.sql
│ │ │ ├── TrigInfo.sql
│ │ │ ├── gen_.txt
│ │ │ ├── gen_able.sql
│ │ │ └── gen_dcon.sql
│ │ └── fk_splitted.sql
│ ├── _Booo
│ │ ├── CheckCheck.sql
│ │ ├── Conntrolnew.sql
│ │ ├── ControlDirect.sql
│ │ ├── FKListToFrom.SQL
│ │ ├── Lockdtab.SQL
│ │ ├── RegenCheck.sql
│ │ ├── ShowFK.SQL
│ │ ├── TFSDTFRG.SQL
│ │ ├── TFSLDRFR.SQL
│ │ ├── TFSTFRAG.SQL
│ │ ├── _Gentab.sql
│ │ ├── dbdesc.sql
│ │ ├── oriGenFix.sql
│ │ ├── pkAutovalid.sql
│ │ ├── show_fkchild.sql
│ │ ├── unload2.sql
│ │ ├── unload3.sql
│ │ └── unload_fixed.sql
│ ├── _ReView.sql
│ ├── _RevView.sql
│ ├── revPackage.sql
│ ├── revPk.sql
│ └── revView.sql
└── trucchi.sql
├── TGenAllFK.sql
├── TGenFk.sql
├── TGenSovFK.sql
├── Trace.sql
├── ar_move_tablespace.sql
├── backup.sql
├── ddl_generator.sql
├── drop_all_objects.sql
├── drop_queue_tables.sql
├── find_in_schema.sql
├── fn_gen_inserts.sql
├── gen_acl_script.sql
├── genera_trigger_storico.sql
├── html_2_text.sql
├── invalid_synonyms.sql
├── lang_integer.sql
├── notificatore.sql
├── show_locks_rac.sql
├── tbd_space.sql
├── win_expdp_full.bat
└── write_clob_to_file.sql
/AllineaSequence2.sql:
--------------------------------------------------------------------------------
1 | spool AllineaSequence.log
2 |
3 | /************************************************************
4 | Copyright Apex-net srl - Via Riccardo Brusi, 151/2 - 47023 Cesena
5 | ------------------------------------------------------------
6 | Autore: Fabio Vassura
7 | Data: 27/12/04
8 | Descrizione : Allineamento Sequence
9 | ************************************************************/
10 |
11 | set serveroutput on size 1000000
12 |
13 | declare
14 | v_NOMETABLE VARCHAR2(80);
15 | v_NOMEPK VARCHAR2(80);
16 | v_MAXVAL NUMBER(9);
17 | begin
18 | DECLARE
19 | CURSOR CUR_SEQ IS
20 | SELECT SEQUENCE_NAME
21 | FROM USER_SEQUENCES;
22 | BEGIN
23 | FOR SEQ IN CUR_SEQ LOOP
24 | BEGIN
25 | v_NOMETABLE := SUBSTR(SEQ.SEQUENCE_NAME, 5);
26 | SELECT COLUMN_NAME
27 | INTO v_NOMEPK
28 | FROM USER_CONSTRAINTS T,
29 | USER_CONS_COLUMNS C
30 | WHERE T.TABLE_NAME = v_NOMETABLE
31 | AND T.CONSTRAINT_TYPE = 'P'
32 | AND T.OWNER = C.OWNER
33 | AND T.CONSTRAINT_NAME = C.CONSTRAINT_NAME;
34 | EXECUTE IMMEDIATE ' SELECT MAX(' || v_NOMEPK || ') FROM '|| v_NOMETABLE INTO v_MAXVAL;
35 | IF(v_MAXVAL > 0 AND v_MAXVAL IS NOT NULL) THEN
36 | EXECUTE IMMEDIATE 'DROP SEQUENCE ' || SEQ.SEQUENCE_NAME;
37 | EXECUTE IMMEDIATE 'CREATE SEQUENCE ' || SEQ.SEQUENCE_NAME || ' START WITH '|| TO_CHAR(v_MAXVAL + 1) ||' MAXVALUE 999999999999999999999999999 MINVALUE 1 NOCYCLE NOCACHE NOORDER';
38 | END IF;
39 | EXCEPTION
40 | WHEN NO_DATA_FOUND THEN NULL;
41 | WHEN TOO_MANY_ROWS THEN DBMS_OUTPUT.PUT_LINE('SEQ_' || v_NOMETABLE || ' non aggiornata');
42 | END;
43 | END LOOP;
44 | END;
45 | END;
46 | /
47 |
48 | spool off;
49 | exit;
50 |
--------------------------------------------------------------------------------
/Autovalid_all_schema.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 |
3 | ------------------------------------------------------------
4 | Autore : Stefano Teodorani
5 | Data : 08/03/99
6 | Descrizione : Ricompilazione oggetti invalidi
7 | ************************************************************/
8 |
9 | set serveroutput on size 1000000
10 |
11 | declare
12 | sql_statement varchar2(200);
13 | cursor_id number;
14 | ret_val number;
15 | also_invalid number;
16 | attempt number;
17 | max_attempt number;
18 | begin
19 |
20 | attempt := 0;
21 | max_attempt := 8;
22 |
23 | dbms_output.put_line(chr(0));
24 | dbms_output.put_line('AUTOVALIDAZIONE DEGLI OGGETTI INVALIDI');
25 | dbms_output.put_line('--------------------------------------');
26 | dbms_output.put_line(chr(0));
27 |
28 | loop
29 | select count(*) into also_invalid
30 | from all_objects
31 | where status = 'INVALID';
32 |
33 | exit when (also_invalid = 0 or attempt = max_attempt);
34 | attempt := attempt + 1;
35 | dbms_output.put_line(chr(0));
36 | dbms_output.put_line('Tentativo numero : '||attempt);
37 | dbms_output.put_line('----------------------------');
38 | for invalid in ( select owner, object_type,
39 | object_name,
40 | decode(object_type,'VIEW',1,'FUNCTION',2,'PROCEDURE',3,'PACKAGE',4,'PACKAGE BODY',5,'TRIGGER',6)
41 | from all_objects
42 | where status = 'INVALID'
43 | and object_type in ('PACKAGE',
44 | 'PACKAGE BODY',
45 | 'FUNCTION',
46 | 'PROCEDURE',
47 | 'TRIGGER',
48 | 'VIEW')
49 | order by 3) loop
50 |
51 | if invalid.object_type = 'PACKAGE BODY' then
52 | sql_statement := 'alter package '||invalid.object_name||' compile body';
53 | else
54 | sql_statement := 'alter '||invalid.object_type||' '||invalid.owner||'.'||invalid.object_name||' compile';
55 |
56 | end if;
57 |
58 | begin
59 | cursor_id := dbms_sql.open_cursor;
60 | dbms_sql.parse(cursor_id, sql_statement, dbms_sql.native);
61 | ret_val := dbms_sql.execute(cursor_id);
62 | dbms_sql.close_cursor(cursor_id);
63 | dbms_output.put_line
64 | (rpad(initcap(invalid.object_type)||' '||invalid.object_name, 32)||' : compilato');
65 | exception when others then
66 | dbms_output.put_line('Problemino in fase di compilazione di : ' ||invalid.object_name);
67 |
68 | end;
69 |
70 | end loop;
71 | end loop;
72 | if attempt = max_attempt then
73 | dbms_output.put_line(chr(0));
74 | dbms_output.put_line('ATTENZIONE');
75 | dbms_output.put_line('Dopo '||attempt||' tentativi, alcuni oggetti sono rimasti invalidi.');
76 | dbms_output.put_line('Effettuare una controllo della base dati');
77 | else
78 | dbms_output.put_line(chr(0));
79 | dbms_output.put_line('Tutti gli oggetti sono stati compilati con successo dopo '||attempt||' tentativi');
80 | end if;
81 | end;
82 | /
83 |
84 |
85 | -- select * from user_objects where status = 'INVALID'
86 |
87 |
88 |
--------------------------------------------------------------------------------
/GenSovFK.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenSovFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni definite
10 | sulle tabelle di uno schema verso un'altro schema
11 |
12 | Parametri:
13 | Nessuno
14 |
15 | */
16 |
17 |
18 | set serveroutput on verify off trims on feedback off
19 |
20 | declare
21 | cname varchar2(50);
22 | cname2 varchar2(50);
23 | r_user varchar2(50);
24 |
25 | cursor c1 is
26 | select c.constraint_name,
27 | c.r_constraint_name cname2,
28 | c.table_name table1,
29 | r.table_name table2,
30 | decode(c.status,'DISABLED','DISABLE',' ') status,
31 | decode(c.delete_rule,'CASCADE',' on delete cascade ',' ') delete_rule,
32 | c.r_owner r_user
33 | from all_constraints c,
34 | all_constraints r
35 | where c.constraint_type='R'
36 | and c.r_constraint_name = r.constraint_name
37 | and c.owner = user
38 | and c.r_owner != user
39 | and c.r_owner = r.owner;
40 |
41 | cursor c2 is
42 | select decode(position,1,'(',',')||column_name colname
43 | from user_cons_columns
44 | where constraint_name = cname
45 | order by position;
46 |
47 | cursor c3 is
48 | select decode(position,1,'(',',')||column_name refcol
49 | from all_cons_columns
50 | where constraint_name = cname2
51 | and owner = r_user
52 | order by position;
53 |
54 | begin
55 | dbms_output.enable(100000);
56 | for q1 in c1 loop
57 | cname := q1.constraint_name;
58 | cname2 := q1.cname2;
59 | r_user := q1.r_user;
60 |
61 | dbms_output.put_line('ALTER TABLE '||q1.table1||' DROP CONSTRAINT '||cname||';');
62 |
63 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
64 | dbms_output.put('FOREIGN KEY ');
65 | for q2 in c2 loop
66 | dbms_output.put(q2.colname);
67 | end loop;
68 | dbms_output.put_line(')');
69 | dbms_output.put('REFERENCES '||q1.table2||' ');
70 | for q3 in c3 loop
71 | dbms_output.put(q3.refcol);
72 | end loop;
73 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
74 | dbms_output.put_line('/');
75 | end loop;
76 | end;
77 | /
78 | set serveroutput off verify on trims off feedback on
--------------------------------------------------------------------------------
/Official Scripts/Data Check/check_date.sql:
--------------------------------------------------------------------------------
1 | create or replace procedure CHECK_DATE as
2 | TROVATO boolean;
3 | nome_tabella varchar2(100);
4 | nome_colonna varchar2(100);
5 | v_SQL varchar2(1000);
6 | a number;
7 | num_records number;
8 | BEGIN
9 |
10 | declare cursor c1 is
11 | select table_name, column_name
12 | from user_tab_columns where data_type = 'DATE';
13 |
14 | begin
15 | dbms_output.enable(99999999);
16 | dbms_output.put_line('Inizio controllo...');
17 | for cursore in c1 loop
18 | -- dbms_output.put_line('Table: [' || cursore.table_name || '] Column: [' || cursore.column_name||']');
19 | v_SQL := 'select count(*) from ' || cursore.table_name || ' where ' || cursore.column_name || ' > trunc(sysdate)';
20 | --v_SQL := 'select count(*) from :1 where :2 > trunc(sysdate) and :1 like ''A%''';
21 | -- dbms_output.put_line(v_SQL);
22 | -- execute immediate v_SQL into num_records using cursore.table_name, cursore.column_name;
23 | execute immediate v_SQL into num_records;
24 | if num_records != 0 then
25 | dbms_output.put_line('Table: [' || cursore.table_name || '] Column: [' || cursore.column_name||']');
26 | end if;
27 | -- a := execute immediate (v_SQL);
28 | -- dbms_output.put_line('Result: ' || to_string(a));
29 | end loop;
30 | dbms_output.put_line('Controllo terminato');
31 | end;
32 |
33 |
34 | END;
35 | /
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_check.sql:
--------------------------------------------------------------------------------
1 | select * from migrazione_log where id > 2000;
2 |
3 |
4 | SET PAGESIZE 255 line 132
5 | --column logon format a15
6 | column SINTASSI format a40 heading 'COPY_THIS_TO_KILL [sid,serial#]'
7 | column APPLICATIVO format a25
8 | column NOME_UTENTE format a20
9 | BREAK ON SCHEMA skip 1 on NOME_UTENTE
10 | -- on " " skip 1
11 |
12 | select decode(audsid, userenv( 'SESSIONID' ), '*' ,' ') " ",
13 | substr(username,1,10) SCHEMA,
14 | osuser NOME_UTENTE,
15 | substr(program,1,25) APPLICATIVO,
16 | -- sid, serial#,
17 | -- TO_CHAR(logon_time,'DD-MM HH:MM:SS') lOGON,
18 | SUBSTR(status,1,1)
19 | from v$session
20 | where username is not null
21 | and status != 'KILLED'
22 | and program like 'sqlplus@mazinga%'
23 | order by " ", username, osuser
24 | /
25 |
26 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_giusti_locks.sql:
--------------------------------------------------------------------------------
1 | set pagesize 50
2 | set linesize 350
3 | column "Pid - Tempo di Login" format a30
4 | column "OS user - Oracle user" format a60
5 | column tabella format a40
6 | break on tabella skip1
7 | prompt "Sessioni Bloccate/Bloccanti con oggetti"
8 | select v.INST_ID "Istanza" ,
9 | to_char(b.spid,'999999') || ' - ' ||to_char(v.logon_time,'dd/mon/yyyy hh24:mi:ss') "Pid - Tempo di Login",
10 | substr(o.owner || '.' ||o.object_name,1,30) tabella,
11 | decode(l.xidusn+l.xidslot+l.xidsqn,
12 | 0,'In attesa ','Bloccata da ') "Stato",
13 | l.os_user_name||'@'||v.machine || ' - ' ||
14 | ' alter system kill session '''||v.sid||','||to_char(v.serial#)||'''; ' "OS user - Comando di kill"
15 | from
16 | gv$locked_object l, all_objects o, gv$session v
17 | , gv$process b
18 | where
19 | l.INST_ID=v.INST_ID and
20 | l.object_id=o.object_id and
21 | l.session_id=v.sid and
22 | v.paddr = b.addr
23 | order by 2,3,4;
24 |
25 | prompt
26 | prompt Oggetti usati dalle transazioni correnti
27 |
28 | break on owner skip1
29 | break on object_name skip1
30 | select
31 | a.owner,
32 | a.object_name,
33 | sid,
34 | serial#,
35 | start_time,
36 | a.object_type
37 | from v$transaction t,
38 | v$session v,
39 | v$locked_object o,
40 | all_objects a
41 | where t.ses_addr=v.saddr
42 | and o.session_id=v.sid
43 | and o.object_id=a.object_id
44 | order by owner,object_name;
45 | Prompt Sessioni attive
46 | select count(*) from gv$session;
47 | break on MACHINE skip
48 | compute sum of CONTEGGIO on machine
49 | Prompt Sessioni di utenti con troppe sessioni aperte
50 | select decode(inst_id,1,'db1',2,'db2',3,'db3','boh') db,machine,count(*) CONTEGGIO
51 | from gv$session group by 1,inst_id,machine having count(*)>2 order by machine;
52 |
53 | Prompt Sessioni delle macchine importanti
54 | select decode(inst_id,1,'db1',2,'db2',3,'db3','boh') db,machine,count(*) CONTEGGIO
55 | from gv$session where machine in ('as1','as2','as3','iasform','db1','db2','db3','timmi')
56 | group by 1,inst_id,machine
57 | order by machine;
58 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_io.sql:
--------------------------------------------------------------------------------
1 | set pagesize 60 linesize 255 newpage 0 feedback off
2 |
3 | column Total_IO format 999999999
4 | column Weight format 999.99
5 | column Drive format a55
6 | column file_name format a55
7 | break on drive skip 2
8 | compute sum of weight on drive
9 |
10 | select df.name Drive,
11 | df.name File_Name,
12 | fs.phyblkrd+fs.phyblkwrt Total_IO,
13 | 100*(fs.phyblkrd+fs.phyblkwrt) /MaxIO Weight
14 | from
15 | v$filestat fs, v$datafile df,
16 | (select max(phyblkrd + phyblkwrt ) MaxIO from v$filestat)
17 | where df.file# = fs.file#
18 | order by Weight desc
19 | ;
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_locks.SQL:
--------------------------------------------------------------------------------
1 | SET ECHO ON
2 | SET TERM ON
3 | SET TIMING OFF
4 | SET HEAD ON
5 | SET VERI OFF
6 | SET FEED OFF
7 | SET PAUSE OFF
8 | SET PAGES 66
9 | SET RECSEP OFF
10 | SET LINES 132
11 | SET ARRAYSIZE 5
12 |
13 | BTITLE OFF
14 | TTITLE OFF
15 |
16 | CLEAR BREAKS
17 | CLEAR COMPUTE
18 | CLEAR COLUMNS
19 | CLEAR SCREEN
20 |
21 | COL l FOR A78 TRUNC
22 |
23 | ACCEPT us_ CHAR PROMPT "Username (LIKE format - default= all): "
24 |
25 | TTITLE CENTER "Locks by users (except type MR) by &&us_" SKIP -
26 | RIGHT ""
27 |
28 | COL username FOR A08 HEAD "USER OS" TRUNC
29 | COL pid FOR 999 HEAD "PID" TRUNC
30 | COL spid FOR A06 HEAD "SID" TRUNC
31 | COL ora FOR A08 HEAD "USER ORA" TRUNC
32 | COL lock FOR A10 HEAD "LOCKS" TRUNC
33 | COL type FOR A27 HEAD "TYPE" WRAPPED
34 | COL lmode FOR A04 HEAD "MODE" TRUNC
35 | COL wait FOR A01 HEAD "W" TRUNC
36 |
37 | BREAK ON username -
38 | ON pid -
39 | ON spid -
40 | ON ora -
41 | ON lock
42 |
43 | SPOOL lockv7
44 |
45 | SELECT p.username ,
46 | p.pid ,
47 | p.spid ,
48 | s.username ora ,
49 | DECODE(l2.type,
50 | 'TX','TRANSACTION ROW-LEVEL' ,
51 | 'RT','REDO-LOG' ,
52 | 'TS','TEMPORARY SEGMENT ' ,
53 | 'TD','TABLE LOCK' ,
54 | 'TM','ROW LOCK' ,
55 | l2.type ) vlock,
56 | DECODE(l2.type,
57 | 'TX','DML LOCK' ,
58 | 'RT','REDO LOG' ,
59 | 'TS','TEMPORARY SEGMENT' ,
60 | 'TD',DECODE(l2.lmode+l2.request ,
61 | 4,'PARSE ' ||
62 | u.name ||
63 | '.' ||
64 | o.name ,
65 | 6,'DDL' ,
66 | l2.lmode+l2.request),
67 | 'TM','DML ' ||
68 | u.name ||
69 | '.' ||
70 | o.name ,
71 | l2.type ) type ,
72 | DECODE(l2.lmode+l2.request ,
73 | 2 ,'RS' ,
74 | 3 ,'RX' ,
75 | 4 ,'S' ,
76 | 5 ,'SRX' ,
77 | 6 ,'X' ,
78 | l2.lmode+l2.request ) lmode ,
79 | DECODE(l2.request ,
80 | 0,NULL ,
81 | 'WAIT' ) wait
82 | FROM v$process p ,
83 | v$_lock l1,
84 | v$lock l2,
85 | v$resource r ,
86 | sys.obj$ o ,
87 | sys.user$ u ,
88 | v$session s
89 | WHERE s.paddr = p.addr
90 | AND s.saddr = l1.saddr
91 | AND l1.raddr = r.addr
92 | AND l2.addr = l1.laddr
93 | AND l2.type <> 'MR'
94 | AND r.id1 = o.obj# (+)
95 | AND o.owner# = u.user# (+)
96 | AND p.username LIKE NVL('&&us_','%')
97 | ORDER BY
98 | 1,
99 | 2,
100 | 3,
101 | 4,
102 | 5
103 | /
104 | SPOOL OFF
105 |
106 |
107 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_processi.sql:
--------------------------------------------------------------------------------
1 | select vb.name NOME,
2 | substr(vp.program,1,20) PROCESSNAME,
3 | vp.spid THREADID,
4 | vs.sid SID
5 | from v$session vs,v$process vp, v$bgprocess vb
6 | where vb.paddr <> '00'
7 | and vb.paddr = vp.addr
8 | and vp.addr = vs.paddr;
9 |
10 | /*
11 |
12 | select
13 | p.spid "Thread ID",
14 | b.name "Background Process",
15 | s.username "User Name",
16 | s.osuser "OS User",
17 | s.status "STATUS",
18 | s.sid "Session ID",
19 | s.serial# "Serial No.",
20 | s.program "OS Program"
21 | from
22 | v$process p,
23 | v$bgprocess b,
24 | v$session s
25 | where
26 | s.paddr = p.addr and b.paddr(+) = p.addr;
27 |
28 | */
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_rollback_usage.sql:
--------------------------------------------------------------------------------
1 |
2 | SELECT r.name "RB NAME ", p.pid "ORACLE PID",
3 | p.spid "SYSTEM PID ", NVL (p.username, 'NO TRANSACTION') "OS USER",
4 | p.terminal FROM v$lock l, v$process p, v$rollname r, v$session s
5 | WHERE l.sid = s.sid(+) AND s.paddr = p.addr
6 | AND TRUNC (l.id1(+)/65536) = r.usn
7 | AND l.type(+) = 'TX'
8 | AND l.lmode(+) = 6 ORDER BY r.name
9 | ;
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_show_dead.SQL:
--------------------------------------------------------------------------------
1 | REM sho_dead.sql
2 | REM Show deadlocks
3 | REM
4 | column Username format A15
5 | column Sid format 9990 heading SID
6 | column Type format A4
7 | column Lmode format 990 heading 'HELD'
8 | column Request format 990 heading 'REQ'
9 | column Id1 format 9999990
10 | column Id2 format 9999990
11 | break on Id1 skip 1 dup
12 | select SN.Username,
13 | sn.osuser,
14 | M.Sid,
15 | M.Type,
16 | DECODE(M.Lmode, 0, 'None',
17 | 1, 'Null',
18 | 2, 'Row Share',
19 | 3, 'Row Excl.',
20 | 4, 'Share',
21 | 5, 'S/Row Excl.',
22 | 6, 'Exclusive',
23 | Lmode, LTRIM(TO_CHAR(Lmode,'990'))) Lmode,
24 | DECODE(M.Request, 0, 'None',
25 | 1, 'Null',
26 | 2, 'Row Share',
27 | 3, 'Row Excl.',
28 | 4, 'Share',
29 | 5, 'S/Row Excl.',
30 | 6, 'Exclusive',
31 | Request, LTRIM(TO_CHAR(M.Request,
32 | '990'))) Request,
33 | M.Id1, M.Id2
34 | from V$SESSION SN, V$LOCK M
35 | where (SN.Sid = M.Sid
36 | and M.Request != 0)
37 | or (SN.Sid = M.Sid
38 | and M.Request = 0 and Lmode != 4
39 | and (id1, id2) in
40 | (select S.Id1, S.Id2
41 | from V$LOCK S
42 | where Request != 0
43 | and S.Id1 = M.Id1
44 | and S.Id2 = M.Id2) )
45 | order by Id1, Id2, M.Request;
46 |
47 | clear breaks
48 | clear columns
49 |
50 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_table_locks.sql:
--------------------------------------------------------------------------------
1 | set pagesize 50
2 | set linesize 350
3 | column "Pid - Tempo di Login" format a30
4 | column "OS user - Oracle user" format a60
5 | column tabella format a40
6 | break on tabella skip1
7 | prompt "Sessioni Bloccate/Bloccanti con oggetti"
8 | select v.INST_ID "Istanza" ,
9 | to_char(b.spid,'999999') || ' - ' ||to_char(v.logon_time,'dd/mon/yyyy hh24:mi:ss') "Pid - Tempo di Login",
10 | substr(o.owner || '.' ||o.object_name,1,30) tabella,
11 | decode(l.xidusn+l.xidslot+l.xidsqn,
12 | 0,'In attesa ','Bloccata da ') "Stato",
13 | l.os_user_name || ' - ' ||
14 | ' alter system kill session '''||v.sid||','||to_char(v.serial#)||'''; ' "OS user - Comando di kill"
15 | from
16 | gv$locked_object l, all_objects o, gv$session v
17 | , gv$process b
18 | where
19 | l.INST_ID=v.INST_ID and
20 | l.object_id=o.object_id and
21 | l.session_id=v.sid and
22 | v.paddr = b.addr
23 | order by 2,3,4;
24 |
25 | prompt
26 | prompt Oggetti usati dalle transazioni correnti
27 |
28 | break on owner skip1
29 | break on object_name skip1
30 | select
31 | a.owner,
32 | a.object_name,
33 | sid,
34 | serial#,
35 | start_time,
36 | a.object_type
37 | from v$transaction t,
38 | v$session v,
39 | v$locked_object o,
40 | all_objects a
41 | where t.ses_addr=v.saddr
42 | and o.session_id=v.sid
43 | and o.object_id=a.object_id
44 | order by owner,object_name;
45 | Prompt Sessioni attive
46 | select count(*) from gv$session;
47 | break on MACHINE skip
48 | compute sum of CONTEGGIO on machine
49 | Prompt Sessioni di utenti con troppe sessioni aperte
50 | select decode(inst_id,1,'db1',2,'db2',3,'db3','boh') db,machine,count(*) CONTEGGIO
51 | from gv$session group by 1,inst_id,machine having count(*)>2 order by machine;
52 |
53 | Prompt Sessioni delle macchine importanti
54 | select decode(inst_id,1,'db1',2,'db2',3,'db3','boh') db,machine,count(*) CONTEGGIO
55 | from gv$session where machine in ('as1','as2','as3','iasform','db1','db2','db3','timmi')
56 | group by 1,inst_id,machine
57 | order by machine;
58 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/_top_cpu_sessions.sql:
--------------------------------------------------------------------------------
1 | set echo off
2 | set feedback off
3 | set linesize 512
4 |
5 | prompt
6 | prompt Top Sessions by CPU consumption
7 | prompt
8 |
9 | column sid format 999 heading "SID"
10 | column username format a20 heading "User Name"
11 | column command format a20 heading "Command"
12 | column osuser format a20 heading "OS User"
13 | column process format a20 heading "OS Process"
14 | column machine format a20 heading "Machine"
15 | column value format 99,999 heading "CPU Time"
16 |
17 | select
18 | s.sid sid,
19 | s.username username,
20 | UPPER(DECODE(command,
21 | 1,'Create Table',2,'Insert',3,'Select',
22 | 4,'Create Cluster',5,'Alter Cluster',6,'Update',
23 | 7,'Delete', 8,'Drop Cluster', 9,'Create Index',
24 | 10,'Drop Index', 11,'Alter Index', 12,'Drop Table',
25 | 13,'Create Sequencfe', 14,'Alter Sequence', 15,'Alter Table',
26 | 16,'Drop Sequence', 17,'Grant', 18,'Revoke',
27 | 19,'Create Synonym', 20,'Drop Synonym', 21,'Create View',
28 | 22,'Drop View', 23,'Validate Index', 24,'Create Procedure',
29 | 25,'Alter Procedure', 26,'Lock Table', 27,'No Operation',
30 | 28,'Rename', 29,'Comment', 30,'Audit',
31 | 31,'NoAudit', 32,'Create Database Link', 33,'Drop Database Link',
32 | 34,'Create Database', 35,'Alter Database', 36,'Create Rollback Segment',
33 | 37,'Alter Rollback Segment', 38,'Drop Rollback Segment', 39,'Create Tablespace',
34 | 40,'Alter Tablespace', 41,'Drop Tablespace', 42,'Alter Sessions',
35 | 43,'Alter User', 44,'Commit', 45,'Rollback',
36 | 46,'Savepoint', 47,'PL/SQL Execute', 48,'Set Transaction',
37 | 49,'Alter System Switch Log', 50,'Explain Plan', 51,'Create User',
38 | 52,'Create Role', 53,'Drop User', 54,'Drop Role',
39 | 55,'Set Role', 56,'Create Schema', 57,'Create Control File',
40 | 58,'Alter Tracing', 59,'Create Trigger', 60,'Alter Trigger',
41 | 61,'Drop Trigger', 62,'Analyze Table', 63,'Analyze Index',
42 | 64,'Analyze Cluster', 65,'Create Profile', 66,'Drop Profile',
43 | 67,'Alter Profile', 68,'Drop Procedure', 69,'Drop Procedure',
44 | 70,'Alter Resource Cost', 71,'Create Snapshot Log', 72,'Alter Snapshot Log',
45 | 73,'Drop Snapshot Log', 74,'Create Snapshot', 75,'Alter Snapshot',
46 | 76,'Drop Snapshot', 79,'Alter Role', 85,'Truncate Table',
47 | 86,'Truncate Cluster', 88,'Alter View', 91,'Create Function',
48 | 92,'Alter Function', 93,'Drop Function', 94,'Create Package',
49 | 95,'Alter Package', 96,'Drop Package', 97,'Create Package Body',
50 | 98,'Alter Package Body', 99,'Drop Package Body')) command,
51 | s.osuser osuser,
52 | s.machine machine,
53 | s.process process,
54 | t.value value
55 | from
56 | v$session s,
57 | v$sesstat t,
58 | v$statname n
59 | where
60 | s.sid = t.sid
61 | and
62 | t.statistic# = n.statistic#
63 | and
64 | n.name = 'CPU used by this session'
65 | and
66 | t.value > 0
67 | and
68 | audsid > 0
69 | order by
70 | t.value desc;
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/datafile_timestamp.sql:
--------------------------------------------------------------------------------
1 | /*
2 | ===========================================================
3 | Filename...: datafile_timestamp.sql
4 | Author.....: Stefano Teodorani
5 | Release....: 1.0 - 08-may-1999
6 | Description: Estrae il timestamp dei datafiles
7 | Notes......: Occorre connettersi come SYS
8 | ===========================================================
9 | */
10 |
11 | set pagesize 80
12 | set feedback off
13 | set verify off
14 | set echo off
15 | set linesize 132
16 | column file_name format a40
17 |
18 | select
19 | file_id,
20 | fecrc_tim creation_date,
21 | file_name,
22 | tablespace_name
23 | from
24 | x$kccfe int,
25 | dba_data_files dba
26 | where
27 | dba.file_id = int.indx + 1
28 | order by file_id;
29 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/free_space.sql:
--------------------------------------------------------------------------------
1 | /*
2 | ===========================================================
3 | Filename...: user_space.sql
4 | Author.....: Stefano Teodorani
5 | Release....: 1.0 - 08-may-1998
6 | Description: Mostra lo spazio occupato e disponibile per utente
7 | Notes......: none
8 | ===========================================================
9 | */
10 |
11 | set heading on linesize 500 pagesize 1000 termout on echo off feedback off verify off trims on
12 |
13 | col Username format a20 heading 'UTENTE'
14 | col BYTES_A format 999,999,999,999 HEADING 'SPAZIO|OCCUPATO'
15 | col TOT_TABLESPACE format 999,999,999,999 HEADING 'TOTALE|SPAZIO' noprint
16 | col TOTALE_TABLESPACE format 999,999,999,999 HEADING 'TOTALE|SPAZIO'
17 | col PCT format 99.99 HEADING 'PCT'
18 | col GRAPH format a30 HEADING 'GRAPH'
19 | col Created format a11 HEADING 'DATA|CREAZIONE'
20 |
21 | compute sum of BYTES_A on report
22 | compute sum of BYTES_A on TABLESPACE
23 |
24 | break on report
25 | break ON TABLESPACE
26 |
27 | spool %WINDIR%\temp\VisSpace.txt
28 |
29 | select
30 | a.Username,
31 | a.tablespace_name TABLESPACE,
32 | to_char(c.Created,'DD-Mon-YYYY') CREATED,
33 | a.bytes BYTES_A,
34 | sum(b.bytes) TOT_TABLESPACE,
35 | (a.bytes/sum(b.bytes))*100 PCT
36 | from
37 | dba_ts_quotas a,
38 | dba_data_files b,
39 | all_users c
40 | where
41 | a.tablespace_name = b.tablespace_name
42 | and a.Username = c.username
43 | and a.tablespace_name NOT in ('SYSTEM','RBS','TEMP','TOOLS','INDX')
44 | group by
45 | a.Username,
46 | a.tablespace_name,
47 | to_char(c.Created,'DD-Mon-YYYY'), a.bytes
48 | order by 5 desc
49 | ;
50 |
51 | select
52 | tablespace_name,
53 | sum(bytes) TOTALE_TABLESPACE
54 | from
55 | dba_data_files
56 | where
57 | tablespace_name NOT in ('SYSTEM','RBS','TEMP','TOOLS','INDX')
58 | group by
59 | tablespace_name
60 | /
61 |
62 | spool off;
63 |
--------------------------------------------------------------------------------
/Official Scripts/Instance Check/who.sql:
--------------------------------------------------------------------------------
1 | /*
2 | ===========================================================
3 | Filename...: who.sql
4 | Author.....: Stefano Teodorani
5 | Release....: 1.0 - 08-may-1998
6 | Description: Elenca tutti gli utenti esistenti
7 | Notes......: none
8 | ===========================================================
9 | */
10 |
11 | SET PAGESIZE 555 line 1132
12 | --column logon format a15
13 | column SINTASSI format a40 heading 'COPY_THIS_TO_KILL [sid,serial#]'
14 | column APPLICATIVO format a25
15 | column NOME_UTENTE format a20
16 | BREAK ON SCHEMA skip 1 on NOME_UTENTE
17 | -- on " " skip 1
18 |
19 | select '>> alter system kill session '''||sid||','||serial#||''';' SINTASSI ,
20 | decode(audsid, userenv( 'SESSIONID' ), '*' ,' ') " ",
21 | substr(username,1,10) SCHEMA,
22 | osuser NOME_UTENTE,
23 | process PROCESS,
24 | substr(program,1,25) APPLICATIVO,
25 | -- sid, serial#,
26 | -- TO_CHAR(logon_time,'DD-MM HH:MM:SS') lOGON,
27 | SUBSTR(status,1,1)
28 | from v$session
29 | where username is not null
30 | and status != 'KILLED'
31 | and sid =&1 or &1 is null
32 | --and osuser like 'sara%'
33 | order by " ", username, osuser
34 | /
35 |
36 |
37 | -- select distinct sid "My SID is:" from v$mystat;
38 |
39 | -- select userenv('SESSIONID') "My AUSID is:" from dual;
40 |
41 |
--------------------------------------------------------------------------------
/Official Scripts/Object Check/fk_splitted.sql:
--------------------------------------------------------------------------------
1 | -- Creazione tabella temporanea
2 | -- ----------------------------
3 | DROP TABLE test;
4 |
5 | create table test
6 | as
7 | select column_name, constraint_name , table_name from user_cons_columns
8 | where constraint_name in (select constraint_name from user_constraints where constraint_type = 'R')
9 | ;
10 |
11 | -- Aggiunta campo della nome pk relativa
12 | -- -------------------------------------
13 | alter table test add (pkname varchar(30));
14 |
15 | -- Aggiunta campo flag di pk
16 | -- -------------------------
17 | alter table test add (pkflag number(1));
18 |
19 | -- Rimuovo le fk con un solo campo
20 | -- -------------------------------
21 | BEGIN
22 | LOOP
23 | DELETE FROM test
24 | WHERE ROWID IN (SELECT MIN (ROWID)
25 | FROM test
26 | GROUP BY constraint_name
27 | HAVING COUNT (*) = 1);
28 | EXIT WHEN SQL%NOTFOUND;
29 | END LOOP;
30 | COMMIT;
31 | END;
32 | /
33 |
34 | --- --------------
35 |
36 | -- Aggiunge il nome della pk
37 |
38 | declare
39 | v_table_name varchar2(30);
40 | v_column_name varchar2(30);
41 | v_constraint_name varchar2(30);
42 | v_pkname varchar2(30);
43 | ispk number(30);
44 |
45 | cursor c1 is
46 | select column_name, table_name, constraint_name
47 | from test;
48 |
49 | begin
50 |
51 | open c1;
52 | loop
53 | fetch c1 into v_column_name, v_table_name, v_constraint_name;
54 | exit when c1%NOTFOUND;
55 | begin
56 | select constraint_name into v_pkname
57 | from user_constraints
58 | where constraint_type = 'P'
59 | and table_name = v_table_name;
60 |
61 | update test
62 | set pkname = v_pkname
63 | where table_name = v_table_name;
64 |
65 | --dbms_output.put_line(v_pkname ||'-'||v_table_name);
66 | end;
67 | end loop;
68 | close c1;
69 | end;
70 | /
71 |
72 | -- -------------------
73 |
74 | -- aggiornamento flag di pk
75 | set serveroutput on
76 | declare
77 | v_table_name varchar2(30);
78 | v_column_name varchar2(30);
79 | v_constraint_name varchar2(30);
80 | v_pkname varchar2(30);
81 | ispk number(30);
82 |
83 | cursor c1 is
84 | select column_name, table_name, constraint_name, pkname
85 | from test
86 | ;
87 |
88 | begin
89 | dbms_output.enable(1000000);
90 | open c1;
91 | loop
92 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname;
93 | exit when c1%NOTFOUND;
94 | begin
95 | update test a
96 | set a.pkflag = 1
97 | where a.table_name = v_table_name
98 | and a.column_name in (
99 | select column_name
100 | from user_cons_columns
101 | where constraint_name = v_pkname
102 | and table_name = v_table_name
103 | )
104 | ;
105 | -- dbms_output.put_line(v_column_name||' - '||v_table_name||' - '||v_pkname);
106 | end;
107 | end loop;
108 | close c1;
109 | end;
110 | /
111 |
112 |
113 | -- report
114 | set serveroutput on
115 | declare
116 | v_table_name varchar2(30);
117 | v_column_name varchar2(30);
118 | v_constraint_name varchar2(30);
119 | v_pkname varchar2(30);
120 | v_pkflag number(1);
121 | v_total_rows number(30);
122 | v_pk_rows number(30);
123 | v_no_pk_rows number(30);
124 | a number(1);
125 |
126 | cursor c1 is
127 | select column_name, table_name, constraint_name, pkname, pkflag
128 | from test
129 | ;
130 |
131 | begin
132 | dbms_output.enable(1000000);
133 | open c1;
134 | loop
135 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname, v_pkflag;
136 | exit when c1%NOTFOUND;
137 | begin
138 | select count(*) into v_total_rows
139 | from test
140 | where constraint_name = v_constraint_name;
141 |
142 | select count(*) into v_pk_rows
143 | from test
144 | where constraint_name = v_constraint_name
145 | and pkflag is not null;
146 |
147 | select count(*) into v_no_pk_rows
148 | from test
149 | where constraint_name = v_constraint_name
150 | and pkflag is null;
151 |
152 | if (v_total_rows = v_pk_rows) or (v_total_rows = v_no_pk_rows) then
153 | a := 0;
154 | else
155 | dbms_output.put_line('FK Name: '||v_constraint_name ||', '|| 'No.of fields:'||v_total_rows||', '||'PK Fields:'|| v_pk_rows||', '||'No key fields:'|| v_no_pk_rows);
156 | end if;
157 | end;
158 | end loop;
159 | close c1;
160 | end;
161 | /
162 |
163 | drop table test;
--------------------------------------------------------------------------------
/Official Scripts/Object Check/notnull_without_default.sql:
--------------------------------------------------------------------------------
1 | /*
2 | ===========================================================
3 | Filename...: notnull_without_default.sql
4 | Author.....: Stefano Teodorani
5 | Release....: 1.0 - 14-sep-2000
6 | Description: Verifica l'esistenza di campi not null senza default
7 | Notes......: Sono esclusi dall'estrazione le primary key
8 | ===========================================================
9 | */
10 |
11 | set serveroutput on
12 |
13 | declare
14 | cursor c1 is
15 | select
16 | data_default,
17 | default_length,
18 | column_name,
19 | table_name,
20 | nullable
21 | from
22 | user_tab_columns,
23 | tab
24 | where tab.tname = user_tab_columns.table_name
25 | and tabtype = 'TABLE';
26 |
27 |
28 | v_data_default varchar2(255);
29 | v_default_length number(38);
30 | v_column_name varchar2(35);
31 | v_table_name varchar2(35);
32 | v_nullable varchar2(1);
33 | v_num_rec number(10);
34 |
35 | begin
36 | dbms_output.enable(900000);
37 | open c1;
38 | loop
39 | fetch c1 into v_data_default, v_default_length, v_column_name, v_table_name, v_nullable;
40 | exit when c1%NOTFOUND;
41 |
42 | if v_nullable = 'N' and v_default_length is null then
43 |
44 | select count(*) into v_num_rec
45 | from
46 | user_indexes a,
47 | user_cons_columns b,
48 | user_constraints c
49 | where
50 | a.table_name = v_table_name
51 | and a.table_name = b.table_name
52 | and b.constraint_name = c.constraint_name
53 | and b.constraint_name = a.index_name
54 | and b.column_name = v_column_name
55 | and c.constraint_type = 'P';
56 |
57 | if v_num_rec != 0 then
58 | -- dbms_output.put_line(substr(v_data_default,1, v_default_length));
59 | dbms_output.put_line('Table: ' || rpad(v_table_name,30, '.') || ' Column: ' ||v_column_name);
60 | end if;
61 | end if;
62 |
63 | end loop;
64 | close c1;
65 | end;
66 | /
--------------------------------------------------------------------------------
/Official Scripts/Object management/AutoValid.sql:
--------------------------------------------------------------------------------
1 | spool %WINDIR%\temp\AutoValid.log
2 |
3 | /************************************************************
4 |
5 | ------------------------------------------------------------
6 | Autore : Stefano Teodorani
7 | Data : 08/03/99
8 | Descrizione : Ricompilazione oggetti invalidi
9 | ************************************************************/
10 |
11 | set serveroutput on size 1000000
12 |
13 | declare
14 | sql_statement varchar2(200);
15 | cursor_id number;
16 | ret_val number;
17 | also_invalid number;
18 | attempt number;
19 | max_attempt number;
20 | begin
21 |
22 | attempt := 0;
23 | max_attempt := 8;
24 |
25 | dbms_output.put_line(chr(0));
26 | dbms_output.put_line('AUTOVALIDAZIONE DEGLI OGGETTI INVALIDI');
27 | dbms_output.put_line('--------------------------------------');
28 | dbms_output.put_line(chr(0));
29 |
30 | loop
31 | select count(*) into also_invalid
32 | from user_objects
33 | where status = 'INVALID';
34 |
35 | exit when (also_invalid = 0 or attempt = max_attempt);
36 | attempt := attempt + 1;
37 | dbms_output.put_line(chr(0));
38 | dbms_output.put_line('Tentativo numero : '||attempt);
39 | dbms_output.put_line('----------------------------');
40 | for invalid in ( select object_type,
41 | object_name,
42 | decode(object_type,'VIEW',1,'FUNCTION',2,'PROCEDURE',3,'PACKAGE',4,'PACKAGE BODY',5,'TRIGGER',6)
43 | from user_objects
44 | where status = 'INVALID'
45 | and object_type in ('PACKAGE',
46 | 'PACKAGE BODY',
47 | 'FUNCTION',
48 | 'PROCEDURE',
49 | 'TRIGGER',
50 | 'VIEW')
51 | order by 3) loop
52 |
53 | if invalid.object_type = 'PACKAGE BODY' then
54 | sql_statement := 'alter package '||invalid.object_name||' compile body';
55 | else
56 | sql_statement := 'alter '||invalid.object_type||' '||invalid.object_name||' compile';
57 |
58 | end if;
59 |
60 | begin
61 | cursor_id := dbms_sql.open_cursor;
62 | dbms_sql.parse(cursor_id, sql_statement, dbms_sql.native);
63 | ret_val := dbms_sql.execute(cursor_id);
64 | dbms_sql.close_cursor(cursor_id);
65 | dbms_output.put_line
66 | (rpad(initcap(invalid.object_type)||' '||invalid.object_name, 32)||' : compilato');
67 | exception when others then
68 | dbms_output.put_line('Problemino in fase di compilazione di : ' ||invalid.object_name);
69 |
70 | end;
71 |
72 | end loop;
73 | end loop;
74 | if attempt = max_attempt then
75 | dbms_output.put_line(chr(0));
76 | dbms_output.put_line('ATTENZIONE');
77 | dbms_output.put_line('Dopo '||attempt||' tentativi, alcuni oggetti sono rimasti invalidi.');
78 | dbms_output.put_line('Effettuare una controllo della base dati');
79 | else
80 | dbms_output.put_line(chr(0));
81 | dbms_output.put_line('Tutti gli oggetti sono stati compilati con successo dopo '||attempt||' tentativi');
82 | end if;
83 | end;
84 | /
85 |
86 | spool off;
87 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/Control.sql:
--------------------------------------------------------------------------------
1 | REM control.sql script
2 |
3 | set heading off
4 | set verify off
5 | set feedback off
6 | set show off
7 | set trim on
8 | set pages 0
9 | set pagesize 132
10 | set concat on
11 | spool c:\work\macerata\files\ctl\&1..ctl
12 | SELECT
13 | 'LOAD DATA'||chr(10)
14 | ||'INFILE '''||'c:\work\macerata\files\data\'||lower(table_name)||'.dat'' '||chr(10)
15 | ||'INTO TABLE '||table_name||chr(10)
16 | ||'FIELDS TERMINATED BY ''|'' '||chr(10)
17 | ||'TRAILING NULLCOLS'||chr(10)
18 | ||'('
19 | FROM user_tables
20 | WHERE TABLE_NAME = UPPER('&1');
21 | SELECT decode(rownum,1,' ',' , ')||rpad(column_name,33,' ')
22 | || decode(data_type,
23 | 'VARCHAR2','CHAR NULLIF('|| column_name ||'=BLANKS)',
24 | 'FLOAT', 'DECIMAL EXTERNAL NULLIF('||column_name||'=BLANKS)',
25 | 'NUMBER',
26 | decode(data_precision,
27 | 0, 'INTEGER EXTERNAL NULLIF ('||column_name||'=BLANKS)',
28 | decode(data_scale,0,'INTEGER EXTERNAL NULLIF ('||column_name ||'=BLANKS)',
29 | 'DECIMAL EXTERNAL NULLIF ('||column_name ||'=BLANKS)'
30 | )
31 | ),
32 | 'DATE', 'DATE "DD/MM/YYYY" NULLIF ('||column_name||'=BLANKS)',NULL)
33 | FROM user_tab_columns
34 | WHERE TABLE_NAME = UPPER('&1')
35 | ORDER BY COLUMN_ID;
36 | SELECT ')'
37 | FROM sys.dual;
38 |
39 | spool OFF;
40 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/CreaControlFile.sql:
--------------------------------------------------------------------------------
1 | REM control.sql script
2 |
3 | set heading off
4 | set verify off
5 | set feedback off
6 | set show off
7 | set trim on
8 | set pages 0
9 | set pagesize 132
10 | set concat on
11 | spool c:\temp\&1..ctl
12 | SELECT
13 | 'LOAD DATA'||chr(10)
14 | ||'INFILE '''||'..\'||lower(table_name)||'.dat'' '||chr(10)
15 | ||'INTO TABLE '||table_name||chr(10)
16 | ||'FIELDS TERMINATED BY ''|'' '||chr(10)
17 | ||'TRAILING NULLCOLS'||chr(10)
18 | ||'('
19 | FROM user_tables
20 | WHERE TABLE_NAME = UPPER('&1');
21 | SELECT decode(rownum,1,' ',' , ')||rpad(column_name,33,' ')
22 | || decode(data_type,
23 | 'VARCHAR2','CHAR NULLIF('|| column_name ||'=BLANKS)',
24 | 'FLOAT', 'DECIMAL EXTERNAL NULLIF('||column_name||'=BLANKS)',
25 | 'NUMBER',
26 | decode(data_precision,
27 | 0, 'INTEGER EXTERNAL NULLIF ('||column_name||'=BLANKS)',
28 | decode(data_scale,0,'INTEGER EXTERNAL NULLIF ('||column_name ||'=BLANKS)',
29 | 'DECIMAL EXTERNAL NULLIF ('||column_name ||'=BLANKS)'
30 | )
31 | ),
32 | 'DATE', 'DATE "DD/MM/YYYY" NULLIF ('||column_name||'=BLANKS)',NULL)
33 | FROM user_tab_columns
34 | WHERE TABLE_NAME = UPPER('&1')
35 | ORDER BY COLUMN_ID;
36 | SELECT ')'
37 | FROM sys.dual;
38 |
39 | spool OFF;
40 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/CreaSnap.sql:
--------------------------------------------------------------------------------
1 | SET echo OFF heading off verify off feedback off pages 0 lines 80 trims on
2 | spool c:\temp\crea_snap.sql
3 | set serveroutput on
4 | declare
5 | /* Tables */
6 | cursor ctabs IS
7 | select tname from tab where tabtype = 'TABLE';
8 |
9 | /* Columns */
10 | cursor ccols (t in varchar2)
11 | is select decode(column_id,1,' ',',')
12 | ||rpad(column_name,40) cstr
13 | from user_tab_columns
14 | where table_name = upper(t)
15 | order by column_id;
16 |
17 | begin
18 | dbms_output.enable(1000000);
19 | for rtabs in ctabs loop
20 | dbms_output.put_line('create materialized view ' || rtabs.tname);
21 | dbms_output.put_line('on prebuilt table');
22 | dbms_output.put_line('refresh force on demand');
23 | dbms_output.put_line('as');
24 | dbms_output.put_line('select');
25 | for rcols in ccols (rtabs.tname) loop
26 | dbms_output.put_line(rcols.cstr);
27 | end loop;
28 | dbms_output.put_line('from');
29 | dbms_output.put_line(rtabs.tname||'@dwsource');
30 | dbms_output.put_line('/');
31 | end loop;
32 | end;
33 | /
34 |
35 | declare
36 | /* Tables */
37 | cursor ctabs IS
38 | select tname from tab where tabtype = 'TABLE';
39 |
40 | begin
41 | dbms_output.enable(1000000);
42 | for rtabs in ctabs loop
43 | dbms_output.put_line('exec dbms_snapshot.refresh('''|| rtabs.tname ||''');');
44 | END LOOP;
45 | end;
46 | /
47 |
48 | declare
49 | /* Tables */
50 | cursor ctabs IS
51 | select tname from tab where tabtype = 'TABLE';
52 |
53 | begin
54 | dbms_output.enable(1000000);
55 | for rtabs in ctabs loop
56 | dbms_output.put_line('drop snapshot '|| rtabs.tname || ';');
57 | END LOOP;
58 | end;
59 | /
60 | set echo ON serveroutput off feedback on verify on pages 999
61 | spool off
--------------------------------------------------------------------------------
/Official Scripts/Object management/DelTabs.SQL:
--------------------------------------------------------------------------------
1 | set heading off pagesize 0
2 | spool c:\temp\delete.sql
3 | select 'delete '||tname ||';' from tab where tabtype = 'TABLE';
4 | spool off
5 | @c:\temp\delete.sql
6 |
7 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/DisTrig.sql:
--------------------------------------------------------------------------------
1 | /**********************************************************************
2 |
3 | **********************************************************************
4 | *** Modulo : ------
5 | *** RDBMS : Oracle
6 | *** Autore :
7 | *** Versione :
8 | *** Descrizione : Script per la riabilitazione dei constraints
9 | ******************************************************************************/
10 | set echo off
11 | set heading off
12 | set feedback off
13 | set termout off
14 | set space 0
15 | set newpage 0
16 | set pagesize 0
17 | set verify off
18 |
19 | spool dis_tr.sql
20 | select 'spool report.lst ' from dual;
21 | select 'alter trigger '||trigger_name ||' disable;' from user_triggers where status = 'ENABLED'
22 | /
23 | select 'spool off ;' from dual;
24 | spool off
25 | set space 1
26 | set newpage 1
27 | set pagesize 24
28 | set heading on
29 | set feedback on
30 | set echo on
31 | set termout on
32 | @dis_tr.sql
33 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/EnaCons.sql:
--------------------------------------------------------------------------------
1 | /**********************************************************************
2 |
3 | **********************************************************************
4 | *** Modulo : ------
5 | *** RDBMS : Oracle
6 | *** Autore :
7 | *** Versione :
8 | *** Descrizione : Script per la riabilitazione dei constraints
9 | ******************************************************************************/
10 | set echo off
11 | set heading off
12 | set feedback off
13 | set termout off
14 | set space 0
15 | set newpage 0
16 | set pagesize 0
17 | set verify off
18 |
19 | spool ena_fk.sql
20 | select 'spool report.lst ' from dual;
21 | select 'alter table '||table_name ||' enable constraint '|| chr(10) || constraint_name|| ';'
22 | from user_constraints
23 | where constraint_type ='R'
24 | and status = 'DISABLED'
25 | /
26 | select 'spool off ;' from dual;
27 | spool off
28 | set space 1
29 | set newpage 1
30 | set pagesize 24
31 | set heading on
32 | set feedback on
33 | set echo on
34 | set termout on
35 | set verify on
36 | @ena_fk.sql
37 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/FKList.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenAllFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 |
11 | Parametri:
12 | 1. none
13 |
14 | */
15 |
16 | set serveroutput on verify off trims on feedback off
17 |
18 | declare
19 | cname varchar2(50);
20 | cname2 varchar2(50);
21 | r_user varchar2(50);
22 |
23 | cursor c1 is
24 | select c.constraint_name,
25 | c.r_constraint_name cname2,
26 | c.table_name table1,
27 | r.table_name table2,
28 | decode(c.status,'DISABLED','DISABLE',' ') status,
29 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
30 | c.r_owner r_user
31 | from all_constraints c,
32 | all_constraints r
33 | where c.constraint_type='R'
34 | and c.r_constraint_name = r.constraint_name
35 | and c.owner = user
36 | and c.r_owner = r.owner
37 | union
38 | select c.constraint_name,c.r_constraint_name cname2,
39 | c.table_name table1, r.table_name table2,
40 | decode(c.status,'DISABLED','DISABLE',' ') status,
41 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
42 | c.r_owner r_user
43 | from user_constraints c,
44 | user_constraints r
45 | where c.constraint_type='R' and
46 | c.r_constraint_name = r.constraint_name
47 | ;
48 |
49 | cursor c2 is
50 | select decode(position,1,'(',',')||column_name colname
51 | from user_cons_columns
52 | where constraint_name = cname
53 | order by position;
54 |
55 | cursor c3 is
56 | select decode(position,1,'(',',')||column_name refcol
57 | from all_cons_columns
58 | where constraint_name = cname2
59 | and owner = r_user
60 | order by position;
61 |
62 | begin
63 | dbms_output.enable(100000);
64 | for q1 in c1 loop
65 | cname := q1.constraint_name;
66 | cname2 := q1.cname2;
67 | r_user := q1.r_user;
68 |
69 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
70 | dbms_output.put('FOREIGN KEY ');
71 | for q2 in c2 loop
72 | dbms_output.put(q2.colname);
73 | end loop;
74 | dbms_output.put_line(')');
75 | dbms_output.put('REFERENCES '||q1.table2||' ');
76 | for q3 in c3 loop
77 | dbms_output.put(q3.refcol);
78 | end loop;
79 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
80 | dbms_output.put_line('/');
81 | end loop;
82 | end;
83 | /
84 | set serveroutput off verify on trims off feedback on;
85 |
86 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/FKListTo.SQL:
--------------------------------------------------------------------------------
1 | rem ===================================================
2 | rem TFkList.sql
3 | rem -----------
4 | rem Ultima revisione:
5 | rem r1.0 del 28/04/99
6 | rem
7 | rem Descrizione:
8 | rem Ricostruzione della Foreign key indicando
9 | rem come parametro il nome della tabella
10 | rem
11 | rem Parametri:
12 | rem 1. Nome della tabella
13 | rem ===================================================
14 |
15 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
16 |
17 | set serveroutput on verify off trims on feedback off linesize 255 termout on
18 |
19 | declare
20 | cname varchar2(50);
21 | cname2 varchar2(50);
22 | r_user varchar2(50);
23 | cursor c1 is
24 | select c.constraint_name,
25 | c.r_constraint_name cname2,
26 | c.table_name table1,
27 | r.table_name table2,
28 | decode(c.status,'DISABLED','DISABLE',' ') status,
29 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
30 | c.r_owner r_user
31 | from all_constraints c,
32 | all_constraints r
33 | where c.constraint_type='R'
34 | and c.r_constraint_name = r.constraint_name
35 | and c.table_name = upper('&nome_tabella')
36 | and c.owner = user
37 | and c.r_owner = r.owner;
38 | cursor c2 is
39 | select decode(position,1,'(',',')||column_name colname
40 | from user_cons_columns
41 | where constraint_name = cname
42 | order by position;
43 | cursor c3 is
44 | select decode(position,1,'(',',')||column_name refcol
45 | from all_cons_columns
46 | where constraint_name = cname2
47 | and owner = r_user
48 | order by position;
49 | begin
50 | dbms_output.enable(999999);
51 | dbms_output.put_line(chr(0));
52 | for q1 in c1 loop
53 | cname := q1.constraint_name;
54 | cname2 := q1.cname2;
55 | r_user := q1.r_user;
56 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
57 | dbms_output.put('FOREIGN KEY ');
58 | for q2 in c2 loop
59 | dbms_output.put(q2.colname);
60 | end loop;
61 | dbms_output.put_line(')');
62 | dbms_output.put('REFERENCES '||q1.table2||' ');
63 | for q3 in c3 loop
64 | dbms_output.put(q3.refcol);
65 | end loop;
66 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
67 | dbms_output.put_line('/');
68 | end loop;
69 | dbms_output.put_line(chr(0));
70 | end;
71 | /
72 | set serveroutput off verify on trims off feedback on linesize 100 termout on;
--------------------------------------------------------------------------------
/Official Scripts/Object management/FKUpdateField.sql:
--------------------------------------------------------------------------------
1 | set serveroutput on verify off linesize 132
2 |
3 | declare
4 | cursor c1 is
5 | select utc.table_name, utc.column_name , utc.data_type , uc.constraint_name
6 | from user_tab_columns utc
7 | join user_cons_columns ucc on (
8 | utc.table_name = ucc.table_name and utc.column_name = ucc.column_name)
9 | join user_constraints uc on (
10 | uc.constraint_name = ucc.constraint_name)
11 | where 1=1
12 | and uc.constraint_type = 'P'
13 | and utc.data_type not in ('NUMBER', 'DATE', 'BLOB', 'CBLOB')
14 | and utc.table_name not in ('ZZ_OBJECTS')
15 | ;
16 |
17 | cursor c2 (cname varchar2) is
18 | select table_name, column_name
19 | from user_constraints natural join user_cons_columns
20 | where constraint_type='R' and r_constraint_name = cname
21 | ;
22 |
23 | begin
24 | for q1 in c1 loop
25 |
26 | dbms_output.put_line('Elaboro: '||q1.table_name);
27 | dbms_output.put_line('=========================');
28 | dbms_output.put_line('update '||q1.table_name || ' set ' || q1.column_name || '= upper(' || q1.column_name ||');');
29 |
30 | for q2 in c2(q1.constraint_name) loop
31 | dbms_output.put_line('update '||q2.table_name || ' set ' || q2.column_name || '= upper(' || q2.column_name ||');');
32 | end loop;
33 |
34 | dbms_output.put_line('');
35 | end loop;
36 | end;
37 | /
38 |
39 |
40 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/FkListFrom.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenAllFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 | DA e VERSO la tabella passata come parametro.
11 |
12 | Parametri:
13 | 1. Nome Tabella
14 |
15 | */
16 |
17 | set serveroutput on verify off trims on feedback off
18 |
19 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
20 |
21 | declare
22 | cname varchar2(50);
23 | cname2 varchar2(50);
24 | r_user varchar2(50);
25 |
26 | cursor c1 is
27 | select c.constraint_name,
28 | c.r_constraint_name cname2,
29 | c.table_name table1,
30 | r.table_name table2,
31 | decode(c.status,'DISABLED','DISABLE',' ') status,
32 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
33 | c.r_owner r_user
34 | from all_constraints c,
35 | all_constraints r
36 | where c.constraint_type='R'
37 | and c.r_constraint_name = r.constraint_name
38 | and c.table_name = upper('&nome_tabella')
39 | and c.owner = user
40 | and c.r_owner = r.owner
41 | union
42 | select c.constraint_name,c.r_constraint_name cname2,
43 | c.table_name table1, r.table_name table2,
44 | decode(c.status,'DISABLED','DISABLE',' ') status,
45 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
46 | c.r_owner r_user
47 | from user_constraints c,
48 | user_constraints r
49 | where c.constraint_type='R' and
50 | c.r_constraint_name = r.constraint_name and
51 | r.table_name = upper('&nome_tabella');
52 |
53 | cursor c2 is
54 | select decode(position,1,'(',',')||column_name colname
55 | from user_cons_columns
56 | where constraint_name = cname
57 | order by position;
58 |
59 | cursor c3 is
60 | select decode(position,1,'(',',')||column_name refcol
61 | from all_cons_columns
62 | where constraint_name = cname2
63 | and owner = r_user
64 | order by position;
65 |
66 | begin
67 | dbms_output.enable(100000);
68 | for q1 in c1 loop
69 | cname := q1.constraint_name;
70 | cname2 := q1.cname2;
71 | r_user := q1.r_user;
72 |
73 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
74 | dbms_output.put('FOREIGN KEY ');
75 | for q2 in c2 loop
76 | dbms_output.put(q2.colname);
77 | end loop;
78 | dbms_output.put_line(')');
79 | dbms_output.put('REFERENCES '||q1.table2||' ');
80 | for q3 in c3 loop
81 | dbms_output.put(q3.refcol);
82 | end loop;
83 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
84 | dbms_output.put_line('/');
85 | end loop;
86 | end;
87 | /
88 | set serveroutput off verify on trims off feedback on;
89 |
90 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/GenFix2.sql:
--------------------------------------------------------------------------------
1 | rem
2 | rem GenFix.sql
3 | rem ----------------
4 | rem Ultima revisione:
5 | rem r2.1 del 17/09/99
6 | rem r2.2 del 24/01/2001, S. Teodorani - Aggiunta clausola CASCADE CONSTRAINT in DROP TABELLA
7 | rem Aggiuto elenco delle colonne nello statement di insert
8 | rem Descrizione:
9 | rem Ricostruzione degli statements necessari per rigenerare una tabella.
10 | rem Input:
11 | rem Nome della Tabella
12 | rem Output:
13 | rem Script c:\temp\GenFix.txt
14 | rem Nota:
15 | rem Deve esistere la directory C:\Temp
16 | rem
17 |
18 | ACCEPT nome_tabella CHAR PROMPT 'Tabella: '
19 |
20 | undef tab;
21 | set echo off
22 |
23 | set pages 0 feed off verify off lines 150 trims on
24 | col c1 format a80
25 |
26 | spool c:\temp\GenFix.txt
27 |
28 |
29 | select 'ALTER TABLE '||table_name||' DROP CONSTRAINT '||constraint_name||';'
30 | from user_constraints
31 | where r_constraint_name in (
32 | select constraint_name
33 | from user_constraints
34 | where table_name=upper('&nome_tabella')
35 | and constraint_type in ('P','U')
36 | );
37 |
38 |
39 | set serveroutput on
40 |
41 |
42 | /* Creazione delle Foreign Key */
43 | /* --------------------------- */
44 |
45 | declare
46 |
47 | cname varchar2(50);
48 | cname2 varchar2(50);
49 | r_user varchar2(50);
50 |
51 | cursor c1 is
52 | select c.constraint_name,
53 | c.r_constraint_name cname2,
54 | c.table_name table1,
55 | r.table_name table2,
56 | decode(c.status,'DISABLED','DISABLE',' ') status,
57 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
58 | c.r_owner r_user
59 | from all_constraints c,
60 | all_constraints r
61 | where c.constraint_type='R'
62 | and c.r_constraint_name = r.constraint_name
63 | and c.table_name = upper('&nome_tabella')
64 | and c.owner = user
65 | and c.r_owner = r.owner
66 | union
67 | select c.constraint_name,c.r_constraint_name cname2,
68 | c.table_name table1, r.table_name table2,
69 | decode(c.status,'DISABLED','DISABLE',' ') status,
70 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
71 | c.r_owner r_user
72 | from user_constraints c,
73 | user_constraints r
74 | where c.constraint_type='R' and
75 | c.r_constraint_name = r.constraint_name and
76 | r.table_name = upper('&nome_tabella');
77 |
78 | cursor c2 is
79 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) colname
80 | from user_cons_columns
81 | where constraint_name = cname
82 | order by position;
83 |
84 | cursor c3 is
85 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) refcol
86 | from all_cons_columns
87 | where constraint_name = cname2
88 | and owner = r_user
89 | order by position;
90 |
91 | begin
92 | dbms_output.enable(999999);
93 | for q1 in c1 loop
94 | cname := q1.constraint_name;
95 | cname2 := q1.cname2;
96 | r_user := q1.r_user;
97 |
98 | dbms_output.put('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname||CHR(10)||' FOREIGN KEY');
99 | for q2 in c2 loop
100 | dbms_output.put_line(q2.colname);
101 | end loop;
102 | dbms_output.put(') '||CHR(10)||' REFERENCES '||q1.table2);
103 | for q3 in c3 loop
104 | dbms_output.put_line(q3.refcol);
105 | end loop;
106 | dbms_output.put(')'||q1.delete_rule||q1.status||';');
107 | dbms_output.put_line(chr(10));
108 | end loop;
109 | end;
110 | /
111 |
112 | spool off
113 | set echo on feed on verify on
114 |
115 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/ShowInvalid.sql:
--------------------------------------------------------------------------------
1 | select 'ALTER '||decode(object_type,'PACKAGE BODY','PACKAGE',object_type) ||' '||object_name|| ' COMPILE;' OGGETTI_INVALIDI
2 | from user_objects where status = 'INVALID'
3 | /
4 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/TruncTabs.SQL:
--------------------------------------------------------------------------------
1 | set heading off pagesize 0
2 | spool c:\temp\truncate.sql
3 | select 'truncate table '||tname ||';' from tab where tabtype = 'TABLE';
4 | spool off
5 | @c:\temp\truncate.sql
6 |
7 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/_DisCons.sql:
--------------------------------------------------------------------------------
1 | /**********************************************************************
2 | *** RDBMS : Oracle
3 | *** Autore : Stefano Teodorani
4 | *** Versione : 1.0 - 10-dec-201
5 | *** Descrizione : Disable foreign-key constraints
6 | ******************************************************************************/
7 | set echo off
8 | set heading off
9 | set feedback off
10 | set space 0
11 | set newpage 0
12 | set pagesize 0
13 | set termout off
14 | spool dis_fk.sql
15 | select 'spool report.lst ' from dual;
16 | select 'alter table '||table_name ||' disable constraint '|| chr(10) || constraint_name|| ';'
17 | from user_constraints
18 | where constraint_type ='R'
19 | and status = 'ENABLED'
20 | /
21 | select 'spool off ;' from dual;
22 | spool off
23 | set space 1
24 | set newpage 1
25 | set pagesize 24
26 | set heading on
27 | set feedback on
28 | set echo on
29 | set termout on
30 | @dis_fk.sql
31 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/dropallfk.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | dropallfk.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 | DA e VERSO la tabella passata come parametro.
11 |
12 | Parametri:
13 | 1. Nome Tabella
14 |
15 | */
16 |
17 | set serveroutput on verify off trims on feedback off
18 |
19 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
20 |
21 | declare
22 | cname varchar2(50);
23 | cname2 varchar2(50);
24 | r_user varchar2(50);
25 |
26 | cursor c1 is
27 | select c.constraint_name,
28 | c.r_constraint_name cname2,
29 | c.table_name table1,
30 | r.table_name table2,
31 | decode(c.status,'DISABLED','DISABLE',' ') status,
32 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
33 | c.r_owner r_user
34 | from all_constraints c,
35 | all_constraints r
36 | where c.constraint_type='R'
37 | and c.r_constraint_name = r.constraint_name
38 | and c.table_name like upper('&nome_tabella') || '%'
39 | and c.owner = user
40 | and c.r_owner = r.owner
41 | union
42 | select c.constraint_name,c.r_constraint_name cname2,
43 | c.table_name table1, r.table_name table2,
44 | decode(c.status,'DISABLED','DISABLE',' ') status,
45 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
46 | c.r_owner r_user
47 | from user_constraints c,
48 | user_constraints r
49 | where c.constraint_type='R' and
50 | c.r_constraint_name = r.constraint_name and
51 | r.table_name = upper('&nome_tabella');
52 |
53 | cursor c2 is
54 | select decode(position,1,'(',',')||column_name colname
55 | from user_cons_columns
56 | where constraint_name = cname
57 | order by position;
58 |
59 | cursor c3 is
60 | select decode(position,1,'(',',')||column_name refcol
61 | from all_cons_columns
62 | where constraint_name = cname2
63 | and owner = r_user
64 | order by position;
65 |
66 | begin
67 | dbms_output.enable(100000);
68 | for q1 in c1 loop
69 | cname := q1.constraint_name;
70 | cname2 := q1.cname2;
71 | r_user := q1.r_user;
72 |
73 | dbms_output.put_line('ALTER TABLE '||q1.table1||' DROP CONSTRAINT '||cname||';');
74 | end loop;
75 | end;
76 | /
77 | set serveroutput off verify on trims off feedback on;
78 |
79 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/enatrig.sql:
--------------------------------------------------------------------------------
1 | /**********************************************************************
2 |
3 | **********************************************************************
4 | *** Modulo : ------
5 | *** RDBMS : Oracle
6 | *** Autore :
7 | *** Versione :
8 | *** Descrizione : Script per la riabilitazione dei constraints
9 | ******************************************************************************/
10 | set echo off
11 | set heading off
12 | set feedback off
13 | set termout off
14 | set space 0
15 | set newpage 0
16 | set pagesize 0
17 | set verify off
18 |
19 | spool ena_tr.sql
20 | select 'spool report.lst ' from dual;
21 | select 'alter trigger '||trigger_name ||' enable;' from user_triggers where status = 'DISABLED'
22 | /
23 | select 'spool off ;' from dual;
24 | spool off
25 | set space 1
26 | set newpage 1
27 | set pagesize 24
28 | set heading on
29 | set feedback on
30 | set echo on
31 | set termout on
32 | @ena_tr.sql
33 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/fk_splitted.sql:
--------------------------------------------------------------------------------
1 | -- Creazione tabella temporanea
2 | -- ----------------------------
3 | DROP TABLE test;
4 |
5 | create table test
6 | as
7 | select column_name, constraint_name , table_name from user_cons_columns
8 | where constraint_name in (select constraint_name from user_constraints where constraint_type = 'R')
9 | ;
10 |
11 | -- Aggiunta campo della nome pk relativa
12 | -- -------------------------------------
13 | alter table test add (pkname varchar(30));
14 |
15 | -- Aggiunta campo flag di pk
16 | -- -------------------------
17 | alter table test add (pkflag number(1));
18 |
19 | -- Rimuovo le fk con un solo campo
20 | -- -------------------------------
21 | BEGIN
22 | LOOP
23 | DELETE FROM test
24 | WHERE ROWID IN (SELECT MIN (ROWID)
25 | FROM test
26 | GROUP BY constraint_name
27 | HAVING COUNT (*) = 1);
28 | EXIT WHEN SQL%NOTFOUND;
29 | END LOOP;
30 | COMMIT;
31 | END;
32 | /
33 |
34 | --- --------------
35 |
36 | -- Aggiunge il nome della pk
37 |
38 | declare
39 | v_table_name varchar2(30);
40 | v_column_name varchar2(30);
41 | v_constraint_name varchar2(30);
42 | v_pkname varchar2(30);
43 | ispk number(30);
44 |
45 | cursor c1 is
46 | select column_name, table_name, constraint_name
47 | from test;
48 |
49 | begin
50 |
51 | open c1;
52 | loop
53 | fetch c1 into v_column_name, v_table_name, v_constraint_name;
54 | exit when c1%NOTFOUND;
55 | begin
56 | select constraint_name into v_pkname
57 | from user_constraints
58 | where constraint_type = 'P'
59 | and table_name = v_table_name;
60 |
61 | update test
62 | set pkname = v_pkname
63 | where table_name = v_table_name;
64 |
65 | --dbms_output.put_line(v_pkname ||'-'||v_table_name);
66 | end;
67 | end loop;
68 | close c1;
69 | end;
70 | /
71 |
72 | -- -------------------
73 |
74 | -- aggiornamento flag di pk
75 | set serveroutput on
76 | declare
77 | v_table_name varchar2(30);
78 | v_column_name varchar2(30);
79 | v_constraint_name varchar2(30);
80 | v_pkname varchar2(30);
81 | ispk number(30);
82 |
83 | cursor c1 is
84 | select column_name, table_name, constraint_name, pkname
85 | from test
86 | ;
87 |
88 | begin
89 | dbms_output.enable(1000000);
90 | open c1;
91 | loop
92 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname;
93 | exit when c1%NOTFOUND;
94 | begin
95 | update test a
96 | set a.pkflag = 1
97 | where a.table_name = v_table_name
98 | and a.column_name in (
99 | select column_name
100 | from user_cons_columns
101 | where constraint_name = v_pkname
102 | and table_name = v_table_name
103 | )
104 | ;
105 | -- dbms_output.put_line(v_column_name||' - '||v_table_name||' - '||v_pkname);
106 | end;
107 | end loop;
108 | close c1;
109 | end;
110 | /
111 |
112 |
113 | -- report
114 | set serveroutput on
115 | declare
116 | v_table_name varchar2(30);
117 | v_column_name varchar2(30);
118 | v_constraint_name varchar2(30);
119 | v_pkname varchar2(30);
120 | v_pkflag number(1);
121 | v_total_rows number(30);
122 | v_pk_rows number(30);
123 | v_no_pk_rows number(30);
124 | a number(1);
125 |
126 | cursor c1 is
127 | select column_name, table_name, constraint_name, pkname, pkflag
128 | from test
129 | ;
130 |
131 | begin
132 | dbms_output.enable(1000000);
133 | open c1;
134 | loop
135 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname, v_pkflag;
136 | exit when c1%NOTFOUND;
137 | begin
138 | select count(*) into v_total_rows
139 | from test
140 | where constraint_name = v_constraint_name;
141 |
142 | select count(*) into v_pk_rows
143 | from test
144 | where constraint_name = v_constraint_name
145 | and pkflag is not null;
146 |
147 | select count(*) into v_no_pk_rows
148 | from test
149 | where constraint_name = v_constraint_name
150 | and pkflag is null;
151 |
152 | if (v_total_rows = v_pk_rows) or (v_total_rows = v_no_pk_rows) then
153 | a := 0;
154 | else
155 | dbms_output.put_line('FK Name: '||v_constraint_name ||', '|| 'No.of fields:'||v_total_rows||', '||'PK Fields:'|| v_pk_rows||', '||'No key fields:'|| v_no_pk_rows);
156 | end if;
157 | end;
158 | end loop;
159 | close c1;
160 | end;
161 | /
162 |
163 | drop table test;
--------------------------------------------------------------------------------
/Official Scripts/Object management/grant_select_to_public.sql:
--------------------------------------------------------------------------------
1 | select 'grant select on ' || table_name || ' to public with grant option;' from user_tables;
--------------------------------------------------------------------------------
/Official Scripts/Object management/granttoall.sql:
--------------------------------------------------------------------------------
1 | select 'grant select on '|| tname || ' to public;' from tab where tabtype = 'TABLE';
--------------------------------------------------------------------------------
/Official Scripts/Object management/proc_autovalid.sql:
--------------------------------------------------------------------------------
1 | create or replace procedure autovalid
2 | is
3 | begin
4 | declare
5 | sql_statement varchar2(200);
6 | cursor_id number;
7 | ret_val number;
8 | also_invalid number;
9 | attempt number;
10 | max_attempt number;
11 | begin
12 | dbms_output.enable(100000);
13 | attempt := 0;
14 | max_attempt := 8;
15 | -- dbms_output.put_line(chr(0));
16 | dbms_output.put_line('--------------------------------------');
17 | dbms_output.put_line('AUTOVALIDAZIONE DEGLI OGGETTI INVALIDI');
18 | dbms_output.put_line('--------------------------------------');
19 | -- dbms_output.put_line(chr(0));
20 | loop
21 | select count(*) into also_invalid
22 | from user_objects
23 | where status = 'INVALID';
24 | exit when (also_invalid = 0 or attempt = max_attempt);
25 |
26 | attempt := attempt + 1;
27 | dbms_output.put_line(chr(0));
28 | dbms_output.put_line('Tentativo numero : '||attempt);
29 | dbms_output.put_line('----------------------------');
30 | for invalid in
31 | (select object_type, object_name
32 | , decode(object_type,'VIEW',1,'FUNCTION',2,'PROCEDURE',3,'PACKAGE',4,'PACKAGE BODY',5,'TRIGGER',6)
33 | from user_objects
34 | where status = 'INVALID'
35 | and object_type in ('PACKAGE', 'PACKAGE BODY', 'FUNCTION'
36 | ,'PROCEDURE', 'TRIGGER', 'VIEW')
37 | order by 3)
38 | loop
39 | if invalid.object_type = 'PACKAGE BODY' then
40 | sql_statement := 'alter package '||invalid.object_name||' compile body';
41 | else
42 | sql_statement := 'alter '||invalid.object_type||' '||invalid.object_name||' compile';
43 | end if;
44 | begin
45 | cursor_id := dbms_sql.open_cursor;
46 | dbms_sql.parse(cursor_id, sql_statement, dbms_sql.native);
47 | ret_val := dbms_sql.execute(cursor_id);
48 | dbms_sql.close_cursor(cursor_id);
49 | dbms_output.put_line
50 | (rpad(initcap(invalid.object_type)||' '||invalid.object_name, 32)||' : compilato');
51 |
52 | exception when others then
53 | dbms_output.put_line('Problemino in fase di compilazione di : ' ||invalid.object_name);
54 | end;
55 | end loop;
56 | end loop;
57 | if attempt = max_attempt then
58 | dbms_output.put_line(chr(0));
59 | dbms_output.put_line('ATTENZIONE');
60 | dbms_output.put_line('Dopo '||attempt||' tentativi, alcuni oggetti sono rimasti invalidi.');
61 | dbms_output.put_line('Effettuare una controllo della base dati');
62 | else
63 | dbms_output.put_line(chr(0));
64 | dbms_output.put_line('Tutti gli oggetti sono stati compilati con successo dopo '||attempt||' tentativi');
65 | end if;
66 | end;
67 | end;
68 | /
--------------------------------------------------------------------------------
/Official Scripts/Object management/revGrants.sql:
--------------------------------------------------------------------------------
1 | -- eseguire sullo schema clonato del cliente per creare lo script
2 | -- eseguire poi lo script creato sempre sullo schema clonato
3 |
4 | set feedback off verify off HEADING OFF
5 | SPOOL C:\TEMP\GRANTS.SQL
6 | select 'grant all on ' || tname || ' to public;' from tab where tabtype = 'TABLE';
7 | SPOOL OFF
8 |
9 |
10 |
--------------------------------------------------------------------------------
/Official Scripts/Object management/u_tab_sqlldr_ctl.sql:
--------------------------------------------------------------------------------
1 | REM
2 | REM DBAToolZ NOTE:
3 | REM This script was obtained from DBAToolZ.com
4 | REM It's configured to work with SQL Directory (SQLDIR).
5 | REM SQLDIR is a utility that allows easy organization and
6 | REM execution of SQL*Plus scripts using user-friendly menu.
7 | REM Visit DBAToolZ.com for more details and free SQL scripts.
8 | REM
9 | REM
10 | REM File:
11 | REM u_tab_sqlldr_ctl.sql
12 | REM
13 | REM TAB UTIL
14 | REM
15 | REM Author:
16 | REM Vitaliy Mogilevskiy
17 | REM VMOGILEV
18 | REM (vit100gain@earthlink.net)
19 | REM
20 | REM Purpose:
21 | REM
22 | REM builds SQL*Loader control file for a table
23 | REM
24 | REM
25 | REM Usage:
26 | REM u_tab_sqlldr_ctl.sql
27 | REM
28 | REM Example:
29 | REM u_tab_sqlldr_ctl.sql
30 | REM
31 | REM
32 | REM History:
33 | REM 08-01-1998 VMOGILEV Created
34 | REM
35 | REM
36 |
37 | set feedback off
38 | set verify off
39 |
40 | drop table select_text;
41 |
42 | create table select_text (
43 | text varchar2(2000)
44 | );
45 |
46 | accept 1 prompt "Enter Table Name:"
47 | accept 2 prompt "Enter Table Owner:"
48 |
49 | declare
50 | cursor cur IS
51 | select owner
52 | , table_name
53 | , column_name
54 | , decode(data_type,
55 | 'NUMBER','decimal external',
56 | 'DATE' ,'date (11)'
57 | ,'char ('||DATA_LENGTH||')') data_type
58 | , column_id
59 | from dba_tab_columns
60 | where table_name = upper('&&1')
61 | and owner = upper('&&2')
62 | order by column_id;
63 |
64 | l_curr_line VARCHAR2(2000);
65 | l_owner sys.dba_tables.owner%TYPE;
66 | l_table_name sys.dba_tables.table_name%TYPE;
67 | begin
68 | l_curr_line := '
69 | LOAD DATA
70 | REPLACE
71 | INTO TABLE ';
72 | select owner, table_name
73 | into l_owner, l_table_name
74 | from dba_tables
75 | where table_name = upper('&&1')
76 | and owner = upper('&&2');
77 | l_curr_line := l_curr_line||l_owner||'.'||l_table_name||'
78 | FIELDS TERMINATED BY '||''''||','||''''||'
79 | OPTIONALLY ENCLOSED BY '||''''||'"'||''''||'
80 | TRAILING NULLCOLS
81 | (';
82 | for rec in cur loop
83 | if rec.column_id = 1 then
84 | l_curr_line := l_curr_line||'
85 | '||rpad(rec.column_name,35)||rec.data_type;
86 | else
87 | l_curr_line := l_curr_line||'
88 | , '||rpad(rec.column_name,35)||rec.data_type;
89 | end if;
90 | end loop;
91 | l_curr_line := l_curr_line||')';
92 | insert into select_text values(l_curr_line);
93 | commit;
94 | end;
95 | /
96 |
97 | set pages 900
98 | set lines 80
99 | col text format a80
100 | set head off
101 | set term off
102 | set trimspool on
103 |
104 | spool select.tmp
105 |
106 | select * from select_text;
107 |
108 | spool off
109 | set term on
110 |
111 | ed select.tmp
112 |
--------------------------------------------------------------------------------
/Official Scripts/Others/CreaUte.sql:
--------------------------------------------------------------------------------
1 | undef login
2 |
3 | ACCEPT login CHAR PROMPT 'Nome utente: '
4 |
5 | create user &&login
6 | identified by &&login
7 | default tablespace users
8 | temporary tablespace temp
9 | quota unlimited on users;
10 |
11 | grant connect, resource to &&login;
12 |
--------------------------------------------------------------------------------
/Official Scripts/Others/catexp9.sql:
--------------------------------------------------------------------------------
1 |
2 | -- modificata da eseguire su sys di oracle 9.2.0.1 per far funzionare export del
3 | -- client 8 su server 9.
4 |
5 | -- Dopo la modifica
6 | -- Export da server 9:
7 |
8 | -- Export da client 9 eseguito correttamente, creato file exp9.dmp
9 | -- Export da client 8 eseguito correttamente, creato file exp8.dmp
10 | -- import di exp9.dmp con il client 9 .....
11 | -- import di exp8.dmp con il client 8 ....
12 |
13 |
14 | CREATE OR REPLACE view exu81rls
15 | (objown,objnam,policy,polown,polsch,polfun,stmts,chkopt,enabled,spolicy)
16 | AS select u.name, o.name, r.pname, r.pfschma, r.ppname, r.pfname,
17 | decode(bitand(r.stmt_type,1), 0,'', 'SELECT,')
18 | || decode(bitand(r.stmt_type,2), 0,'', 'INSERT,')
19 | || decode(bitand(r.stmt_type,4), 0,'', 'UPDATE,')
20 | || decode(bitand(r.stmt_type,8), 0,'', 'DELETE,'),
21 | r.check_opt, r.enable_flag,
22 | DECODE(BITAND(r.stmt_type, 16), 0, 0, 1)
23 | from user$ u, obj$ o, rls$ r
24 | where u.user# = o.owner#
25 | and r.obj# = o.obj#
26 | and (uid = 0 or
27 | uid = o.owner# or
28 | exists ( select * from session_roles where role='SELECT_CATALOG_ROLE')
29 | );
30 |
31 | grant select on sys.exu81rls to public;
--------------------------------------------------------------------------------
/Official Scripts/Others/dropsyn.SQL:
--------------------------------------------------------------------------------
1 | spool c:\temp\~view.sql
2 | select 'drop view '|| tname ||';' from tab where tabtype = 'VIEW'
3 | /
4 | @c:\temp\~view.sql
5 |
--------------------------------------------------------------------------------
/Official Scripts/Others/dropview.SQL:
--------------------------------------------------------------------------------
1 | spool c:\temp\~view.sql
2 | select 'drop view '|| tname ||';' from tab where tabtype = 'VIEW'
3 | /
4 | @c:\temp\~view.sql
5 |
--------------------------------------------------------------------------------
/Official Scripts/Reverse engeenering/CrIndex.sql:
--------------------------------------------------------------------------------
1 | /*
2 | BIJU'S ORACLE PAGE
3 |
4 | cr_index.sql
5 |
6 | Purpose
7 |
8 | Index creation script generated based on the base table owner and name passed in as parameter. Wild character may be used (%) in the paramter list. Screen output saved at /tmp/crindex.sql
9 |
10 | Parameters
11 |
12 | 1. Table Owner (Wild character % may be used)
13 | 2. Table Name (Wild character % may be used)
14 | Command Line
15 |
16 | SQL> @cr_index tableowner tablename
17 |
18 | The Script
19 |
20 | NOTA: ESEGUIRE DA SYSTEM
21 |
22 | */
23 | rem
24 | rem Script to create index creation DDL
25 | rem
26 | rem Biju Thomas
27 | rem
28 | rem Provide the owner name and table name along with the script with a space
29 | rem
30 | set serveroutput on feedback off verify off pages 0
31 | /*
32 | Inserire il nome utente e il nome della tabella
33 | */
34 | spool c:\temp\crindex.sql
35 | declare
36 | wuser varchar2 (15) := '&1';
37 | wtable varchar2 (30) := '&2';
38 | /* Indexes */
39 | cursor cind is
40 | select owner, table_owner, table_name, index_name, ini_trans, max_trans,
41 | tablespace_name, initial_extent/1024 initial_extent,
42 | next_extent/1024 next_extent, min_extents, max_extents,
43 | pct_increase, decode(uniqueness,'UNIQUE','UNIQUE') unq
44 | from dba_indexes
45 | where table_owner like upper(wuser) and
46 | table_name like upper(wtable);
47 | /* Index columns */
48 | cursor ccol (o in varchar2, t in varchar2, i in varchar2) is
49 | select decode(column_position,1,'(',',')||
50 | rpad(column_name,40) cl
51 | from dba_ind_columns
52 | where table_name = upper(t) and
53 | index_name = upper(i) and
54 | index_owner = upper(o)
55 | order by column_position;
56 | wcount number := 0;
57 | begin
58 | dbms_output.enable(100000);
59 | for rind in cind loop
60 | wcount := wcount + 1;
61 | dbms_output.put_line('create '||rind.unq||' index '|| rind.owner || '.' || rind.index_name||' on '||rind.table_owner||'.'|| rind.table_name);
62 | for rcol in ccol (rind.owner, rind.table_name, rind.index_name) loop
63 | dbms_output.put_line(rcol.cl);
64 | end loop;
65 | dbms_output.put_line(') initrans ' || rind.ini_trans || ' maxtrans ' || rind.max_trans);
66 | dbms_output.put_line('tablespace ' || rind.tablespace_name);
67 | dbms_output.put_line('storage (initial ' || rind.initial_extent || 'K next ' || rind.next_extent || 'K pctincrease ' || rind.pct_increase);
68 | dbms_output.put_line('minextents ' || rind.min_extents || ' maxextents '
69 | || rind.max_extents || ' )');
70 | dbms_output.put_line('/');
71 | end loop;
72 | if wcount =0 then
73 | dbms_output.put_line('******************************************************');
74 | dbms_output.put_line('* *');
75 | dbms_output.put_line('* Plese Verify Input Parameters... No Matches Found! *');
76 | dbms_output.put_line('* *');
77 | dbms_output.put_line('******************************************************');
78 | end if;
79 | end;
80 | /
81 | set serveroutput off feedback on verify on pages 999
82 | spool off
83 | prompt
84 | prompt Output saved at c:\temp\crindex.sql
85 |
--------------------------------------------------------------------------------
/Official Scripts/Tuning/SGA.sql:
--------------------------------------------------------------------------------
1 | ttitle -
2 | center 'SGA Cache Hit Ratios' skip 2
3 |
4 | set pagesize 60
5 | set heading off
6 | set termout off
7 |
8 | col lib_hit format 999.999 justify right
9 | col dict_hit format 999.999 justify right
10 | col db_hit format 999.999 justify right
11 | col ss_share_mem format 999.99 justify right
12 | col ss_persit_mem format 999.99 justify right
13 | col ss_avg_users_cursor format 999.99 justify right
14 | col ss_avg_stmt_exe format 999.99 justify right
15 |
16 | col val2 new_val lib noprint
17 | select 1-(sum(reloads)/sum(pins)) val2
18 | from v$librarycache
19 | /
20 | col val2 new_val dict noprint
21 | select 1-(sum(getmisses)/sum(gets)) val2
22 | from v$rowcache
23 | /
24 | col val2 new_val phys_reads noprint
25 | select value val2
26 | from v$sysstat
27 | where name = 'physical reads'
28 | /
29 | col val2 new_val log1_reads noprint
30 | select value val2
31 | from v$sysstat
32 | where name = 'db block gets'
33 | /
34 | col val2 new_val log2_reads noprint
35 | select value val2
36 | from v$sysstat
37 | where name = 'consistent gets'
38 | /
39 | col val2 new_val chr noprint
40 | select 1-(&phys_reads / (&log1_reads + &log2_reads)) val2
41 | from dual
42 | /
43 |
44 | col val2 new_val avg_users_cursor noprint
45 | col val3 new_val avg_stmts_exe noprint
46 | select sum(users_opening)/count(*) val2,
47 | sum(executions)/count(*) val3
48 | from v$sqlarea
49 | /
50 |
51 | set termout on
52 | set heading off
53 |
54 | select 'Data Block Buffer Hit Ratio : '||&chr db_hit_ratio,
55 | 'Shared SQL Pool ',
56 | ' Dictionary Hit Ratio : '||&dict dict_hit,
57 | ' Shared SQL Buffers (Library Cache) ',
58 | ' Cache Hit Ratio : '||&lib lib_hit,
59 | ' Avg. Users/Stmt : '||
60 | &avg_users_cursor||' ',
61 | ' Avg. Executes/Stmt : '||
62 | &avg_stmts_exe||' '
63 | from dual
64 | /
65 |
--------------------------------------------------------------------------------
/Official Scripts/Tuning/TuneBuf2.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | September 16, 1998
4 |
5 | Optimally Tuning the SGA
6 | This Tip of the Week entry comes from Biyi Iredele,
7 | an Oralce DBA for Shell Petroleum Development
8 | Company Of Nigeria in Warri, Delta State, Nigeria.
9 |
10 | Correct tuning of the SGA is vital to the optimal
11 | performance of the database.
12 |
13 | This PLSQL script queries the SGA of an instance and
14 | advises if and where modifications are needed in the INIT.ORA file.
15 |
16 | */
17 |
18 | REM*********************************************************
19 | REM File : tunebuf2.sql (for PLSQL)
20 | REM
21 | REM Function : This PLSQL script queries the SGA of an instance
22 | REM and advises if modifications are needed in the
23 | REM INIT.ORA file.
24 | REM
25 | REM Usage : SQL > @tunebuf2.sql
26 | REM
27 | REM Author : C. Olubiyi IREDELE
28 | REM*********************************************************
29 |
30 | set serveroutput on
31 |
32 | set feedback off
33 |
34 | DECLARE
35 | libcac number(8,2);
36 | rowcac number(8,2);
37 | bufcac number(8,2);
38 | redlog number(8,2);
39 | spsize number;
40 | blkbuf number;
41 | logbuf number;
42 |
43 | BEGIN
44 |
45 | select value into redlog from v$sysstat
46 | where name = 'redo log space requests';
47 |
48 | select 100*(sum(pins)-sum(reloads))/sum(pins) into libcac
49 | from v$librarycache;
50 |
51 | select 100*(sum(gets)-sum(getmisses))/sum(gets) into rowcac
52 | from v$rowcache;
53 |
54 | select 100*(cur.value + con.value - phys.value)/(cur.value + con.value) into bufcac
55 | from v$sysstat cur,
56 | v$sysstat con,
57 | v$sysstat phys,
58 | v$statname ncu,
59 | v$statname nco,
60 | v$statname nph
61 | where cur.statistic# = ncu.statistic#
62 | and ncu.name = 'db block gets'
63 | and con.statistic# = nco.statistic#
64 | and nco.name = 'consistent gets'
65 | and phys.statistic# = nph.statistic#
66 | and nph.name = 'physical reads';
67 |
68 | select value into spsize
69 | from v$parameter
70 | where name = 'shared_pool_size';
71 |
72 | select value into blkbuf
73 | from v$parameter
74 | where name = 'db_block_buffers';
75 |
76 | select value into logbuf
77 | from v$parameter
78 | where name = 'log_buffer';
79 |
80 | dbms_output.put_line('> SGA CACHE STATISTICS');
81 | dbms_output.put_line('> ********************');
82 | dbms_output.put_line('> SQL Cache Hit rate = '||libcac);
83 | dbms_output.put_line('> Dict Cache Hit rate = '||rowcac);
84 | dbms_output.put_line('> Buffer Cache Hit rate = '||bufcac);
85 | dbms_output.put_line('> Redo Log space requests = '||redlog);
86 | dbms_output.put_line('> ');
87 | dbms_output.put_line('> INIT.ORA SETTING');
88 | dbms_output.put_line('> ****************');
89 | dbms_output.put_line('> Shared Pool Size = '||spsize||' Bytes');
90 | dbms_output.put_line('> DB Block Buffer = '||blkbuf||' Blocks');
91 | dbms_output.put_line('> Log Buffer = '||logbuf||' Bytes');
92 | dbms_output.put_line('> ');
93 |
94 | if libcac < 99 then dbms_output.put_line('*** HINT: Library Cache too low! Increase the Shared Pool Size.'); END IF;
95 | if rowcac < 85 then dbms_output.put_line('*** HINT: Row Cache too low! Increase the Shared Pool Size.'); END IF;
96 | if bufcac < 90 then dbms_output.put_line('*** HINT: Buffer Cache too low! Increase the DB Block Buffer value.'); END IF;
97 | if redlog > 100 then dbms_output.put_line('*** HINT: Log Buffer value is rather low!'); END IF;
98 |
99 | END;
100 | /
101 |
--------------------------------------------------------------------------------
/Official Scripts/Tuning/latches.sql:
--------------------------------------------------------------------------------
1 | SET ECHO off
2 | REM NAME: TFSLATCH.SQL
3 | REM USAGE:"@path/tfslatch"
4 | REM ------------------------------------------------------------------------
5 | REM AUTHOR:
6 | REM Virag Saksena, Craig A. Shallahamer, Oracle US
7 | REM (c)1994 Oracle Corporation
8 | REM ------------------------------------------------------------------------
9 | REM Main text of script follows
10 |
11 | ttitle -
12 | center 'Latch Contention Report' skip 3
13 |
14 | col name form A25
15 | col gets form 999,999,999
16 | col misses form 999.99
17 | col spins form 999.99
18 | col igets form 999,999,999
19 | col imisses form 999.99
20 |
21 | select name,gets,misses*100/decode(gets,0,1,gets) misses,
22 | spin_gets*100/decode(misses,0,1,misses) spins, immediate_gets igets
23 | ,immediate_misses*100/decode(immediate_gets,0,1,immediate_gets) imisses
24 | from v$latch order by gets + immediate_gets
25 | /
26 |
27 | SET ECHO off
28 | REM NAME: TFSLTSLP.SQL
29 | REM USAGE:"@path/tfsltslp"
30 | REM ------------------------------------------------------------------------
31 | REM AUTHOR:
32 | REM Virag Saksena, Craig A. Shallahamer, Oracle US
33 | REM (c)1994 Oracle Corporation
34 | REM ------------------------------------------------------------------------
35 | REM Main text of script follows:
36 |
37 | col name form A18 trunc
38 | col gets form 999,999,990
39 | col miss form 90.9
40 | col cspins form A6 heading 'spin|sl06'
41 | col csleep1 form A5 heading 'sl01|sl07'
42 | col csleep2 form A5 heading 'sl02|sl08'
43 | col csleep3 form A5 heading 'sl03|sl09'
44 | col csleep4 form A5 heading 'sl04|sl10'
45 | col csleep5 form A5 heading 'sl05|sl11'
46 | col Interval form A12
47 | set recsep off
48 |
49 | select a.name
50 | ,a.gets gets
51 | ,a.misses*100/decode(a.gets,0,1,a.gets) miss
52 | ,to_char(a.spin_gets*100/decode(a.misses,0,1
53 | ,a.misses),'990.9')||
54 | to_char(a.sleep6*100/decode(a.misses,0,1
55 | ,a.misses),'90.9') cspins
56 | ,to_char(a.sleep1*100/decode(a.misses,0,1
57 | ,a.misses),'90.9')||
58 | to_char(a.sleep7*100/decode(a.misses,0,1
59 | ,a.misses),'90.9') csleep1
60 | ,to_char(a.sleep2*100/decode(a.misses,0,1
61 | ,a.misses),'90.9')||
62 | to_char(a.sleep8*100/decode(a.misses,0,1
63 | ,a.misses),'90.9') csleep2
64 | ,to_char(a.sleep3*100/decode(a.misses,0,1
65 | ,a.misses),'90.9')||
66 | to_char(a.sleep9*100/decode(a.misses,0,1
67 | ,a.misses),'90.9') csleep3
68 | ,to_char(a.sleep4*100/decode(a.misses,0,1
69 | ,a.misses),'90.9')||
70 | to_char(a.sleep10*100/decode(a.misses,0,1
71 | ,a.misses),'90.9') csleep4
72 | ,to_char(a.sleep5*100/decode(a.misses,0,1
73 | ,a.misses),'90.9')||
74 | to_char(a.sleep11*100/decode(a.misses,0,1
75 | ,a.misses),'90.9') csleep5
76 | from v$latch a
77 | where a.misses <> 0
78 | order by 2 desc
79 | /
80 |
81 |
82 |
--------------------------------------------------------------------------------
/Official Scripts/Tuning/library_cache.sql:
--------------------------------------------------------------------------------
1 | column namespace heading "Library Object"
2 | column gets format 9,999,999 heading "Gets"
3 | column gethitratio format 999.99 heading "Get Hit%"
4 | column pins format 9,999,999 heading "Pins"
5 | column pinhitratio format 999.99 heading "Pin Hit%"
6 | column reloads format 99,999 heading "Reloads"
7 | column invalidations format 99,999 heading "Invalid"
8 | column db format a10
9 | set pages 58 lines 80
10 | start title80 "Library Caches Report"
11 | define output = rep_out\&db\lib_cache
12 | spool &output
13 | select
14 | namespace,
15 | gets,
16 | gethitratio*100 gethitratio,
17 | pins,
18 | pinhitratio*100 pinhitratio,
19 | RELOADS,
20 | INVALIDATIONS
21 | from
22 | v$librarycache
23 | /
24 | spool off
25 | pause Press enter to continue
26 | set pages 22 lines 80
27 | ttitle off
28 | undef output
--------------------------------------------------------------------------------
/Official Scripts/Tuning/recreating_redolog.sql:
--------------------------------------------------------------------------------
1 | select s.group#, s.sequence#, s.archived, s.status
2 | , substr( s.first_time, 4, 2 ) || ' '
3 | || substr( s.first_time, 10 ) first_time, f.member
4 | from v$log s, v$logfile f
5 | where s.group# = f.group#
6 | order by 2;
7 |
8 | GROUP# SEQUENCE# A STATUS FIRST_TIME MEMBER
9 | ------ --------- - -------- ---------- --------------------
10 | 2 12150 Y INACTIVE 25 12:15:1 /orad/c22/log21c.dbf
11 | 3 12151 Y INACTIVE 25 17:34:5 /orad/c21/log31c.dbf
12 | 4 12152 Y INACTIVE 25 18:15:1 /orad/c22/log41c.dbf
13 | 5 12153 Y INACTIVE 26 02:15:1 /orad/c21/log51c.dbf
14 | 6 12154 Y INACTIVE 26 02:15:5 /orad/c22/log61c.dbf
15 | 7 12155 Y INACTIVE 26 05:09:3 /orad/c05/log71c.log
16 | 8 12156 Y INACTIVE 26 05:15:1 /orad/c04/log81c.log
17 | 1 12157 N CURRENT 26 11:15:1 /orad/c21/log11c.dbf
18 |
19 | alter system switch logfile;
20 |
21 | goes to next group (in my example, group 1 is ACTIVE for a while, group 2 is CURRENT, others are INCATIVE)
22 |
23 | alter database drop logfile group 3;
24 |
25 | REM os: remove the file
26 | ! rm /orad/c21/log31c.dbf
27 |
28 | alter database add logfile group 3 '/orad/c21/log31c.log' size 300M;
29 |
30 | same_select_as_before (I show you only 1 row)
31 |
32 | GROUP# SEQUENCE# A STATUS FIRST_TIME MEMBER
33 | ------ --------- - ------- ---------- --------------------
34 | 3 0 Y UNUSED 01 00:00:0 /orad/c21/log31c.log
35 |
36 | REM (first_date has no meaning in the previous select for new group)
37 |
38 | alter system switch logfile;
39 |
40 | ecc..
--------------------------------------------------------------------------------
/Official Scripts/Tuning/redo_log.sql:
--------------------------------------------------------------------------------
1 | /*
2 | If the ratio of MISSES to GETS exceeds 1%,
3 | or the ratio of IMMEDIATE_MISSES to (IMMEDIATE_GETS + IMMEDIATE_MISSES)
4 | exceeds 1%, there is latch contention.
5 | */
6 |
7 |
8 | SELECT
9 | substr(ln.name, 1, 20),
10 | gets,
11 | misses,
12 | (gets - misses)/gets,
13 | immediate_gets,
14 | immediate_misses
15 | -- ((immediate_gets + immediate_misses ) - immediate_misses)/immediate_gets
16 | FROM
17 | v$latch l,
18 | v$latchname ln
19 | WHERE ln.name in ('redo allocation', 'redo copy')
20 | and ln.latch# = l.latch#;
21 |
22 |
23 |
24 | /*
25 |
26 | The statistic 'redo log space requests' represents the number
27 | of times that the background was requested to allocate space
28 | in the redo log file.
29 |
30 | It does not represent waiting for space
31 | in the log buffer or for LGWR to finish doing a write.
32 |
33 | The only way to get more disk space is to do a log switch
34 | --which you note is occurring at the time.
35 |
36 | This statistic gives an indication of how many
37 | times a user process waited for space in the redo log.
38 |
39 | The statistic 'redo log space wait time' represents
40 | the amount of time waited for space in the redo log
41 | in 1/100's of a second.
42 |
43 | */
44 |
45 | SELECT name, value
46 | FROM v$sysstat
47 | WHERE name = 'redo log space requests';
48 |
--------------------------------------------------------------------------------
/Official Scripts/Utils/hextodec.sql:
--------------------------------------------------------------------------------
1 | rem -----------------------------------------------------------------------
2 | rem Filename: hex2dec.sql
3 | rem Purpose: Function to convert a Hex number to Decimal
4 | rem Author: Anonymous
5 | rem -----------------------------------------------------------------------
6 |
7 | CREATE OR REPLACE FUNCTION hex2dec (hexnum in char) RETURN number IS
8 | i number;
9 | digits number;
10 | result number := 0;
11 | current_digit char(1);
12 | current_digit_dec number;
13 | BEGIN
14 | digits := length(hexnum);
15 | for i in 1..digits loop
16 | current_digit := SUBSTR(hexnum, i, 1);
17 | if current_digit in ('A','B','C','D','E','F') then
18 | current_digit_dec := ascii(current_digit) - ascii('A') + 10;
19 | else
20 | current_digit_dec := to_number(current_digit);
21 | end if;
22 | result := (result * 16) + current_digit_dec;
23 | end loop;
24 | return result;
25 | END hex2dec;
26 | /
27 | show errors
28 |
29 |
--------------------------------------------------------------------------------
/Script/To Verify/CrTable.sql:
--------------------------------------------------------------------------------
1 | /*
2 | BIJU'S ORACLE PAGE
3 |
4 | cr_table.sql
5 |
6 | Purpose
7 |
8 | Table creation script generated based on the table name passed in as parameter.
9 | Wild characters may be used (%) in the parameter list.
10 | Screen output saved at c:\temp\crtable.sql
11 |
12 | Parameters
13 |
14 | 1. Table Owner (Wild character % may be used)
15 | 2. Table Name (Wild character % may be used)
16 | Command Line
17 |
18 | SQL> @cr_table tableowner tablename
19 |
20 | The Script
21 | NOTA
22 | ESEGUIRE DA SYSTEM
23 | IL PRESENTE SCRIPT NON GENERA EVENTUALI DEFAULT O CHECK CONSTRAINTS
24 | */
25 |
26 | rem Generate table creation script
27 | rem
28 | rem Biju Thomas
29 | rem
30 | rem Pass owner name and table name as parameters
31 | rem
32 | set heading off verify off feedback off pages 0 lines 80 trims on
33 | spool c:\temp\crtable.sql
34 | set serveroutput on
35 | declare
36 | wuser varchar2 (15) := '&1';
37 | wtable varchar2 (30) := '&2';
38 | /* Tables */
39 | cursor ctabs is select table_name, owner, tablespace_name,
40 | initial_extent/1024 initial_extent, pct_free, ini_trans,
41 | next_extent/1024 next_extent, pct_increase, pct_used, max_trans,
42 | min_extents, max_extents
43 | from all_tables where
44 | owner like upper(wuser)
45 | and table_name like upper(wtable);
46 | /* Columns */
47 | cursor ccols (o in varchar2, t in varchar2)
48 | is select decode(column_id,1,'(',',')
49 | ||rpad(column_name,40)
50 | ||rpad(data_type,10)
51 | ||rpad(
52 | decode(data_type,'DATE' ,' '
53 | ,'LONG' ,' '
54 | ,'LONG RAW',' '
55 | ,'RAW' ,decode(data_length,null,null
56 | ,'('||data_length||')')
57 | ,'CHAR' ,decode(data_length,null,null
58 | ,'('||data_length||')')
59 | ,'VARCHAR' ,decode(data_length,null,null
60 | ,'('||data_length||')')
61 | ,'VARCHAR2',decode(data_length,null,null
62 | ,'('||data_length||')')
63 | ,'NUMBER' ,decode(data_precision,null,' '
64 | ,'('||data_precision||
65 | decode(data_scale,null,null,','||data_scale)||')'),'unknown'),8,' ') cstr
66 | from all_tab_columns
67 | where table_name = upper(t)
68 | and owner = upper(o)
69 | order by column_id;
70 | wcount number := 0;
71 | begin
72 | dbms_output.enable(100000);
73 | for rtabs in ctabs loop
74 | wcount := wcount + 1;
75 | dbms_output.put_line('create table ' || rtabs.owner || '.' || rtabs.table_name);
76 | for rcols in ccols (rtabs.owner, rtabs.table_name) loop
77 | dbms_output.put_line(rcols.cstr);
78 | end loop;
79 | dbms_output.put_line(') pctfree ' || rtabs.pct_free || ' pctused ' || rtabs.pct_used);
80 | dbms_output.put_line('initrans ' || rtabs.ini_trans || ' maxtrans ' || rtabs.max_trans);
81 | dbms_output.put_line('tablespace ' || rtabs.tablespace_name);
82 | dbms_output.put_line('storage (initial ' || rtabs.initial_extent || 'K next ' || rtabs.next_extent || 'K pctincrease ' || rtabs.pct_increase);
83 | dbms_output.put_line('minextents ' || rtabs.min_extents || ' maxextents ' || rtabs.max_extents || ' )');
84 | dbms_output.put_line('/');
85 | end loop;
86 | if wcount = 0 then
87 | dbms_output.put_line('******************************************************');
88 | dbms_output.put_line('* *');
89 | dbms_output.put_line('* Plese Verify Input Parameters... No Matches Found! *');
90 | dbms_output.put_line('* *');
91 | dbms_output.put_line('******************************************************');
92 | end if;
93 | end;
94 | /
95 | set serveroutput off feedback on verify on pages 999
96 | spool off
97 | prompt
98 | prompt Output saved at /tmp/crtable.sql
99 |
100 |
101 |
--------------------------------------------------------------------------------
/Script/To Verify/CrTrigger.sql:
--------------------------------------------------------------------------------
1 | /*
2 | BIJU'S ORACLE PAGE
3 |
4 | cr_trig.sql
5 |
6 | Purpose
7 |
8 | Trigger creation script generated based on the trigger name passed in as paramter. Wild characters may be used (%) in the parameter list. Screen output saved at /tmp/crtrig.sql
9 |
10 | Parameters
11 |
12 | 1. Trigger Owner (Wild character % may be used)
13 | 2. Trigger Name (Wild character % may be used)
14 | Command Line
15 |
16 | SQL> @cr_trig triggerowner triggername
17 |
18 | The Script
19 | */
20 | rem
21 | rem Generate Trigger Creation DDL
22 | rem
23 | rem Input : Trigger owner and Trigger name
24 | rem
25 | rem Biju Thomas
26 | rem
27 | set pages 0 feedback off lines 200 trims on echo off long 32000 verify off
28 | spool c:\temp\crtrig.sql
29 | column nl newline
30 | select 'CREATE OR REPLACE TRIGGER', DESCRIPTION, trigger_body, '/' nl
31 | from all_triggers
32 | where owner like upper('&1')
33 | and trigger_name like upper('&2')
34 | /
35 | spool off
36 | set pages 24 feedback on lines 80 verify on
37 | prompt
38 | prompt Output saved at c:\temp\crtrig.sql
39 | prompt
40 |
--------------------------------------------------------------------------------
/Script/To Verify/CrView.sql:
--------------------------------------------------------------------------------
1 | /*
2 | BIJU'S ORACLE PAGE
3 |
4 | cr_view.sql
5 |
6 | Purpose
7 |
8 | View creation script generated based on the view name passed in as paramter. Wild characters may be used (%) in the parameter list. Screen output saved at /tmp/crview.sql
9 |
10 | Parameters
11 |
12 | 1. View Owner (Wild character % may be used)
13 | 2. View Name (Wild character % may be used)
14 | Command Line
15 |
16 | SQL> @cr_view viewowner viewname
17 |
18 | The Script
19 | */
20 | rem
21 | rem Generate view creation script
22 | rem
23 | rem Biju Thomas
24 | rem
25 | rem Pass owner name and view name as parameters
26 | rem
27 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
28 | set pages 0 lines 78 trims on
29 | column vtext format a78 wrap
30 | spool c:\temp\crview.sql
31 | select 'create view '||owner||'.'||view_name||' as ',text,';' vtext
32 | from all_views
33 | where owner like upper('&1')
34 | and view_name like upper('&2')
35 | /
36 | spool off
37 | set termout on feedback on verify on heading on
38 | prompt
39 | prompt Output saved at c:\temp\crview.sql
40 | prompt
41 |
42 |
--------------------------------------------------------------------------------
/Script/To Verify/Indice.htm:
--------------------------------------------------------------------------------
1 | Informazioni
2 | Autovalid
3 | Script di rivalidazione degli oggetti invalidi
4 |
--------------------------------------------------------------------------------
/Script/To Verify/ListTrigger.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListTrigger.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** Trigger: '||upper(object_name)||'>>trigger.sql'||chr(10)|| 'type '||upper(object_name)||'.TRG>> trigger.sql ',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d,
15 | all_triggers at
16 | where o.object_id = d.object_id(+)
17 | and o.object_type = 'TRIGGER'
18 | and o.owner = upper('CQ')
19 | and o.owner = at.owner
20 | and object_name = at.trigger_name
21 | order by d.dlevel desc, o.object_type
22 | /
23 |
24 | spool off
25 | set termout on feedback on verify on heading on
26 |
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/Script/To Verify/ListView.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListView.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** View: '||upper(v.view_name)||'>>viste.sql'||chr(10)|| 'type '||upper(v.view_name)||'.VW>> viste.sql ',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d,
15 | all_views v
16 | where o.object_id = d.object_id(+)
17 | and o.object_type = 'VIEW'
18 | and o.owner = upper('CQ')
19 | and o.owner = v.owner
20 | and v.view_name = o.object_name
21 | order by d.dlevel desc, o.object_type
22 | /
23 |
24 | spool off
25 | set termout on feedback on verify on heading on
26 |
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/Script/To Verify/RedirSyn.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | RedirSyn.sql
4 | ------------
5 | Ultima revisione:
6 | r1.0 del 26/04/99
7 |
8 | Descrizione:
9 | Reindirizzamento dei sinonimi verso un'altro utente
10 |
11 | Parametri:
12 | Utente sovrasocietario verso il quale sono attualmente definiti i sinonimi
13 | Utente sovrasocietario verso il quale si vogliono reindirizzare i sinonimi
14 | */
15 |
16 | ACCEPT utente_vecchio CHAR PROMPT 'Vecchio utente sovrasocietario verso il quale sono attualmente definiti i sinonimi: '
17 | ACCEPT utente_nuovo CHAR PROMPT 'Nuovo utente sovrasocietario verso il quale si vogliono reindirizzare i sinonimi : '
18 |
19 | set echo off
20 | set heading off
21 | set feedback off
22 | set space 0
23 | set newpage 0
24 | set pagesize 0
25 | set verify off
26 |
27 | spool c:\temp\~redir_syn.sql
28 |
29 | select 'DROP SYNONYM '|| SYNONYM_NAME ||';'||CHR(10)|| 'CREATE SYNONYM '|| SYNONYM_NAME ||' FOR &utente_nuovo'||'.'|| SYNONYM_NAME ||';'
30 | from USER_SYNONYMS
31 | where TABLE_OWNER='&utente_vecchio'
32 | /
33 |
34 | spool off;
35 |
36 | set space 1
37 | set newpage 1
38 | set pagesize 24
39 | set heading on
40 | set feedback on
41 | set echo on
42 | set verify on
43 |
44 | PAUSE PREMERE PER ESEGUIRE LO SCRIPT, PER TERMINARE
45 |
46 | @c:\temp\~redir_syn.sql
--------------------------------------------------------------------------------
/Script/To Verify/TFkList.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TFkList.sql
4 | -----------
5 | Ultima revisione:
6 | r1.0 del 28/04/99
7 |
8 | Descrizione:
9 | Ricostruzione della Foreign key indicata
10 | come parametro.
11 |
12 | Parametri:
13 | 1. Nome Foreign key
14 |
15 | */
16 |
17 |
18 | ACCEPT nome_fk CHAR PROMPT 'Nome Foreign-Key: '
19 |
20 | set serveroutput on verify off trims on feedback off linesize 255;
21 |
22 | declare
23 | cname varchar2(50);
24 | cname2 varchar2(50);
25 | r_user varchar2(50);
26 | cursor c1 is
27 | select c.constraint_name,
28 | c.r_constraint_name cname2,
29 | c.table_name table1,
30 | r.table_name table2,
31 | decode(c.status,'DISABLED','DISABLE',' ') status,
32 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
33 | c.r_owner r_user
34 | from all_constraints c,
35 | all_constraints r
36 | where c.constraint_type='R'
37 | and c.r_constraint_name = r.constraint_name
38 | and c.constraint_name = upper('&nome_fk')
39 | and c.owner = user
40 | and c.r_owner = r.owner;
41 | cursor c2 is
42 | select decode(position,1,'(',',')||column_name colname
43 | from user_cons_columns
44 | where constraint_name = cname
45 | order by position;
46 | cursor c3 is
47 | select decode(position,1,'(',',')||column_name refcol
48 | from all_cons_columns
49 | where constraint_name = cname2
50 | and owner = r_user
51 | order by position;
52 | begin
53 | dbms_output.enable(999999);
54 | dbms_output.put_line(chr(0));
55 | for q1 in c1 loop
56 | cname := q1.constraint_name;
57 | cname2 := q1.cname2;
58 | r_user := q1.r_user;
59 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
60 | dbms_output.put('FOREIGN KEY ');
61 | for q2 in c2 loop
62 | dbms_output.put(q2.colname);
63 | end loop;
64 | dbms_output.put_line(')');
65 | dbms_output.put('REFERENCES '||q1.table2||' ');
66 | for q3 in c3 loop
67 | dbms_output.put(q3.refcol);
68 | end loop;
69 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
70 | dbms_output.put_line('/');
71 | end loop;
72 | dbms_output.put_line(chr(0));
73 | end;
74 | /
75 | set serveroutput off verify on trims off feedback on linesize 100;
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Can one monitor how fast a table is imported.sql:
--------------------------------------------------------------------------------
1 | select substr(sql_text,14,instr(sql_text,'(')-16) table_name,
2 | rows_processed,
3 | round((sysdate-to_date(first_load_time,'yyyy-mm-dd hh24:mi:ss'))*24*60,1) minutes,
4 | trunc(rows_processed/((sysdate-to_date(first_load_time,'yyyy-mm-dd hh24:mi:ss'))*24*60)) rows_per_min
5 | from sys.v$sqlarea
6 | where sql_text like 'INSERT INTO "%'
7 | and command_type = 2
8 | and open_versions > 0
9 | ;
10 |
11 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/New_sql/lock.sql:
--------------------------------------------------------------------------------
1 |
2 |
3 | REM =====================================================================
4 | REM Procedure : lockv7
5 | REM Author : Herve Delbarre
6 | REM Subject : List of locks by users(except MR)
7 | REM Oracle db : V7.
8 | REM =====================================================================
9 | SET ECHO ON
10 | SET TERM ON
11 | SET TIMING OFF
12 | SET HEAD ON
13 | SET VERI OFF
14 | SET FEED OFF
15 | SET PAUSE OFF
16 | SET PAGES 66
17 | SET RECSEP OFF
18 | SET LINES 132
19 | SET ARRAYSIZE 5
20 |
21 | BTITLE OFF
22 | TTITLE OFF
23 |
24 | CLEAR BREAKS
25 | CLEAR COMPUTE
26 | CLEAR COLUMNS
27 | CLEAR SCREEN
28 |
29 | COL l FOR A78 TRUNC
30 |
31 |
32 | ACCEPT us_ CHAR PROMPT "Username (LIKE format - default= all): "
33 |
34 |
35 | TTITLE CENTER "Locks by users (except type MR) by &&us_" SKIP -
36 | RIGHT ""
37 |
38 | COL username FOR A08 HEAD "USER OS" TRUNC
39 | COL pid FOR 999 HEAD "PID" TRUNC
40 | COL spid FOR A06 HEAD "SID" TRUNC
41 | COL ora FOR A08 HEAD "USER ORA" TRUNC
42 | COL lock FOR A10 HEAD "LOCKS" TRUNC
43 | COL type FOR A27 HEAD "TYPE" WRAPPED
44 | COL lmode FOR A04 HEAD "MODE" TRUNC
45 | COL wait FOR A01 HEAD "W" TRUNC
46 |
47 | BREAK ON username -
48 | ON pid -
49 | ON spid -
50 | ON ora -
51 | ON lock
52 |
53 | SPOOL lockv7
54 |
55 | SELECT p.username ,
56 | p.pid ,
57 | p.spid ,
58 | s.username ora ,
59 | DECODE(l2.type,
60 | 'TX','TRANSACTION ROW-LEVEL' ,
61 | 'RT','REDO-LOG' ,
62 | 'TS','TEMPORARY SEGMENT ' ,
63 | 'TD','TABLE LOCK' ,
64 | 'TM','ROW LOCK' ,
65 | l2.type ) vlock,
66 | DECODE(l2.type,
67 | 'TX','DML LOCK' ,
68 | 'RT','REDO LOG' ,
69 | 'TS','TEMPORARY SEGMENT' ,
70 | 'TD',DECODE(l2.lmode+l2.request ,
71 | 4,'PARSE ' ||
72 | u.name ||
73 | '.' ||
74 | o.name ,
75 | 6,'DDL' ,
76 | l2.lmode+l2.request),
77 | 'TM','DML ' ||
78 | u.name ||
79 | '.' ||
80 | o.name ,
81 | l2.type ) type ,
82 | DECODE(l2.lmode+l2.request ,
83 | 2 ,'RS' ,
84 | 3 ,'RX' ,
85 | 4 ,'S' ,
86 | 5 ,'SRX' ,
87 | 6 ,'X' ,
88 | l2.lmode+l2.request ) lmode ,
89 | DECODE(l2.request ,
90 | 0,NULL ,
91 | 'WAIT' ) wait
92 | FROM v$process p ,
93 | v$_lock l1,
94 | v$lock l2,
95 | v$resource r ,
96 | sys.obj$ o ,
97 | sys.user$ u ,
98 | v$session s
99 | WHERE s.paddr = p.addr
100 | AND s.saddr = l1.saddr
101 | AND l1.raddr = r.addr
102 | AND l2.addr = l1.laddr
103 | AND l2.type <> 'MR'
104 | AND r.id1 = o.obj# (+)
105 | AND o.owner# = u.user# (+)
106 | AND p.username LIKE NVL('&&us_','%')
107 | ORDER BY
108 | 1,
109 | 2,
110 | 3,
111 | 4,
112 | 5
113 | /
114 | SPOOL OFF
115 |
116 |
117 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/New_sql/whoami.sql:
--------------------------------------------------------------------------------
1 | rem -----------------------------------------------------------------------
2 | rem Filename: whoami.sql
3 | rem Purpose: Reports information about your current database context
4 | rem Author: Frank Naude (frank@onwe.co.za)
5 | rem -----------------------------------------------------------------------
6 |
7 | set termout off
8 | store set store rep
9 | set head off
10 | set pause off
11 | set termout on
12 |
13 | select 'User: '|| user || ' on database ' || global_name,
14 | ' (term='||USERENV('TERMINAL')||
15 | ', audsid='||USERENV('SESSIONID')||')' as MYCONTEXT
16 | from global_name;
17 |
18 | @store
19 | set termout on
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/ListPackage.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListPackage.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** Package: '||upper(object_name)||'>>Package.sql'||chr(10)|| 'type '||upper(object_name)||'.PKS>> package.sql '||chr(10)||'del '||upper(object_name)||'.PKS',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d
15 | where o.object_id = d.object_id(+)
16 | and o.object_type = 'PACKAGE'
17 | and o.owner = upper('RILASCIO')
18 | order by d.dlevel desc, o.object_type
19 | /
20 |
21 | spool off
22 | set termout on feedback on verify on heading on
23 |
24 |
25 |
26 |
27 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/ListProc.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListProc.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** Procedure: '||upper(object_name)||'>>st_proc.sql'||chr(10)|| 'type '||upper(object_name)||'.PRC>> st_proc.sql '||chr(10)||'del '||upper(object_name)||'.PRC',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d
15 | where o.object_id = d.object_id(+)
16 | and o.object_type = 'PROCEDURE'
17 | and o.owner = upper('RILASCIO')
18 | order by d.dlevel desc, o.object_type
19 | /
20 |
21 | spool off
22 | set termout on feedback on verify on heading on
23 |
24 |
25 |
26 |
27 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/ListTrigger.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListTrigger.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** Trigger: '||upper(object_name)||'>>trigger.sql'||chr(10)|| 'type '||upper(object_name)||'.TRG>> trigger.sql '||chr(10)||'del '||upper(object_name)||'.TRG',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d,
15 | all_triggers at
16 | where o.object_id = d.object_id(+)
17 | and o.object_type = 'TRIGGER'
18 | and o.owner = upper('RILASCIO')
19 | and o.owner = at.owner
20 | and object_name = at.trigger_name
21 | order by d.dlevel desc, o.object_type
22 | /
23 |
24 | spool off
25 | set termout on feedback on verify on heading on
26 |
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/ListView.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListView.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** View: '||upper(v.view_name)||'>>view.sql'||chr(10)|| 'type '||upper(v.view_name)||'.VW>> view.sql '||chr(10)||'del '||upper(v.view_name)||'.VW',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d,
15 | all_views v
16 | where o.object_id = d.object_id(+)
17 | and o.object_type = 'VIEW'
18 | and o.owner = upper('RILASCIO')
19 | and o.owner = v.owner
20 | and v.view_name = o.object_name
21 | order by d.dlevel desc, o.object_type
22 | /
23 |
24 | spool off
25 | set termout on feedback on verify on heading on
26 |
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/START_REV.sql:
--------------------------------------------------------------------------------
1 | @@listproc.sql
2 | @@listtrigger.sql
3 | @@listview.sql
4 | @@ListPackage.sql
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Rilascio/_ListFunc.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\ListFunc.bat
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'echo PROMPT *** Function: '||upper(object_name)||'>>function.sql'||chr(10)|| 'type '||upper(object_name)||'.PRC>> function.sql ',
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d
15 | where o.object_id = d.object_id(+)
16 | and o.object_type = 'FUNCTION'
17 | and o.owner = upper('RILASCIO')
18 | order by d.dlevel desc, o.object_type
19 | /
20 |
21 | spool off
22 | set termout on feedback on verify on heading on
23 |
24 |
25 |
26 |
27 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/ListCheck.sql:
--------------------------------------------------------------------------------
1 | /************************************************************
2 | Copyright ESA Software SpA. Via Draghi, 39 RIMINI
3 | ------------------------------------------------------------
4 | Autore : Stefano Teodorani
5 | Data : 26/07/99
6 | Release : 02.00.00
7 | Descrizione : Elenca i check constraints non conformi
8 | ************************************************************/
9 |
10 | PROMPT *** Fix: for.sql
11 | set serveroutput on
12 |
13 | begin
14 | dbms_output.enable(1000000);
15 | for temptable in (select table_name,
16 | constraint_name,
17 | search_condition
18 | from user_constraints
19 | where constraint_type = 'C'
20 | and constraint_name like 'SYS%') loop
21 |
22 | if instr(temptable.search_condition, ' IS NOT NULL') = 0 then
23 | dbms_output.put_line(rpad(temptable.table_name,15) ||' | ' || rpad(temptable.constraint_name,15)||' | ' || temptable.search_condition);
24 | end if;
25 | end loop;
26 |
27 | end;
28 | /
29 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/Locks.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 |
4 | August 1, 1997
5 |
6 | Show List of Locks by Users
7 | This Tip of the Week entry comes from Herve Delbarre, a manager of Oracle Applications and Sun systems in Paris, France.
8 |
9 | This script provides a Unix procedure that shows all locks by a user on an Oracle 7 Release 7.x database.
10 |
11 | */
12 |
13 |
14 | REM =====================================================================
15 | REM Procedure : lockv7
16 | REM Author : Herve Delbarre
17 | REM Subject : List of locks by users(except MR)
18 | REM Oracle db : V7.
19 | REM =====================================================================
20 | SET ECHO OFF
21 | SET TERM ON
22 | SET TIMING OFF
23 | SET HEAD ON
24 | SET VERI OFF
25 | SET FEED OFF
26 | SET PAUSE OFF
27 | SET PAGES 66
28 | SET RECSEP OFF
29 | SET LINES 132
30 | SET ARRAYSIZE 5
31 |
32 | BTITLE OFF
33 | TTITLE OFF
34 |
35 | CLEAR BREAKS
36 | CLEAR COMPUTE
37 | CLEAR COLUMNS
38 | CLEAR SCREEN
39 |
40 | COL l FOR A78 TRUNC
41 |
42 |
43 | ACCEPT us_ CHAR PROMPT "Username (LIKE format - default= all): "
44 |
45 |
46 | TTITLE CENTER "Locks by users (except type MR) by &&us_" SKIP -
47 | RIGHT ""
48 |
49 | COL username FOR A08 HEAD "USER OS" TRUNC
50 | COL pid FOR 999 HEAD "PID" TRUNC
51 | COL spid FOR A06 HEAD "SID" TRUNC
52 | COL ora FOR A08 HEAD "USER ORA" TRUNC
53 | COL lock FOR A10 HEAD "LOCKS" TRUNC
54 | COL type FOR A27 HEAD "TYPE" WRAPPED
55 | COL lmode FOR A04 HEAD "MODE" TRUNC
56 | COL wait FOR A01 HEAD "W" TRUNC
57 |
58 | BREAK ON username -
59 | ON pid -
60 | ON spid -
61 | ON ora -
62 | ON lock
63 |
64 | SPOOL c:\temp\lockv7
65 |
66 | SELECT p.username ,
67 | p.pid ,
68 | p.spid ,
69 | s.username ora ,
70 | DECODE(l2.type,
71 | 'TX','TRANSACTION ROW-LEVEL' ,
72 | 'RT','REDO-LOG' ,
73 | 'TS','TEMPORARY SEGMENT ' ,
74 | 'TD','TABLE LOCK' ,
75 | 'TM','ROW LOCK' ,
76 | l2.type ) vlock,
77 | DECODE(l2.type,
78 | 'TX','DML LOCK' ,
79 | 'RT','REDO LOG' ,
80 | 'TS','TEMPORARY SEGMENT' ,
81 | 'TD',DECODE(l2.lmode+l2.request ,
82 | 4,'PARSE ' ||
83 | u.name ||
84 | '.' ||
85 | o.name ,
86 | 6,'DDL' ,
87 | l2.lmode+l2.request),
88 | 'TM','DML ' ||
89 | u.name ||
90 | '.' ||
91 | o.name ,
92 | l2.type ) type ,
93 | DECODE(l2.lmode+l2.request ,
94 | 2 ,'RS' ,
95 | 3 ,'RX' ,
96 | 4 ,'S' ,
97 | 5 ,'SRX' ,
98 | 6 ,'X' ,
99 | l2.lmode+l2.request ) lmode ,
100 | DECODE(l2.request ,
101 | 0,NULL ,
102 | 'WAIT' ) wait
103 | FROM v$process p ,
104 | v$_lock l1,
105 | v$lock l2,
106 | v$resource r ,
107 | sys.obj$ o ,
108 | sys.user$ u ,
109 | v$session s
110 | WHERE s.paddr = p.addr
111 | AND s.saddr = l1.saddr
112 | AND l1.raddr = r.addr
113 | AND l2.addr = l1.laddr
114 | AND l2.type <> 'MR'
115 | AND r.id1 = o.obj# (+)
116 | AND o.owner# = u.user# (+)
117 | AND p.username LIKE NVL('&&us_','%')
118 | ORDER BY
119 | 1,
120 | 2,
121 | 3,
122 | 4,
123 | 5
124 | /
125 | SPOOL OFF
126 |
127 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/Master.sql:
--------------------------------------------------------------------------------
1 | SELECT uc.table_name master_table,
2 | uc.constraint_name master_key,
3 | uc.constraint_type master_key_type,
4 | uc2.table_name detail_table,
5 | uc2.constraint_name foreign_key
6 | FROM user_constraints uc2,
7 | user_constraints uc
8 | WHERE uc.table_name = UPPER('&Master_table')
9 | AND uc.constraint_type IN ('P', 'U')
10 | AND uc.constraint_name = uc2.r_constraint_name
11 | AND uc2.constraint_type = 'R'
12 | /
13 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/MoveIndexes.txt:
--------------------------------------------------------------------------------
1 | Moving Indexes to a Separate Tablespace
2 | Using A Drop/Add Index Script
3 |
4 | Stephen Rea
5 | University of Arkansas Cooperative Extension Service
6 |
7 | NOTE: USE AT YOUR OWN RISK! MAKE A FULL BACKUP OF YOUR DATABASE FIRST!
8 |
9 |
10 | The move_indexes.sql script will handle both the regular and primary key
11 | indexes, including those involved in foreign key constraints. It can move
12 | indexes based on index name or table name or owner for a single entity or
13 | using a wildcard match. For example, using %, %, % for the index name,
14 | table name, and owner will move all indexes in your database except those
15 | owned by SYS, SYSTEM, and SCOTT. Or, using %, %, FIMS%, all of FIMSMGR
16 | and FIMSARC indexes will be moved.
17 |
18 | The indexes tablespace must have already been created and must be of
19 | sufficient size to hold all of the indexes you are moving. The command
20 | given below will show you the minimum size you'll need for all indexes.
21 | Make it bigger to allow for growth. Also, the default storage clause for
22 | it should probably mirror the DEVELOPMENT tablespace, with pctincrease 1
23 | and maxextents 99.
24 |
25 | SQL> select sum(bytes) from dba_extents where segment_type = 'INDEX'
26 | 2> and tablespace_name = 'DEVELOPMENT'
27 | 3> and owner not in ('SYS','SYSTEM','SCOTT');
28 |
29 | The script took about 15 minutes to perform the moves in our case.
30 | After generating the SQL, it will list it out and ask you if you want
31 | to run that SQL. Be sure you have a current backup before running that
32 | SQL, just in case something goes wrong and you have to restore! The
33 | move_indexes.sql script must be run from user System.
34 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/OBJDIFF.SQL:
--------------------------------------------------------------------------------
1 | /*************************************************************************/
2 | /* objdiff.sql - Lists the objects in a schema that are not in both of */
3 | /* two instances. Uses database links and the SQL MINUS */
4 | /* operator to make the comparison. */
5 | /* */
6 | /* Author: Ken Atkins (katkins@cco.net) */
7 | /* http://www.cco.net/~katkins/oratip */
8 | /* */
9 | /* Written: 5/11/95 */
10 | /* */
11 | /* You need to have a database link setup for any instance that you want */
12 | /* to make a comparison for. */
13 | /* */
14 | /* Please feel free to use and modify this script as long it is not sold */
15 | /* or included in any software without the prior permission of the author*/
16 | /* If you do make some good improvements, please send them to me, and I */
17 | /* can incorporate them in a future version and make them available to */
18 | /* others (giving you credit of course!). */
19 | /* */
20 | /*************************************************************************/
21 | set pagesize 60
22 | set linesize 80
23 | set verify off
24 | set feedback off
25 | set pause off;
26 | --define obj_owner = '&1'
27 | --define inst_1 = '&2'
28 | --define inst_2 = '&3'
29 | accept obj_owner prompt 'Object Owner: '
30 | accept inst_1 prompt 'First instance DB Link (Include @):'
31 | accept inst_2 prompt 'Second instance DB Link (Include @):'
32 |
33 | clear breaks
34 | ttitle off
35 | set heading off
36 |
37 | column datetime noprint new_value datetime
38 | column inst_code1 noprint new_value inst_code1
39 | column inst_code2 noprint new_value inst_code2
40 |
41 | select to_char(sysdate,'MM/DD/YY') datetime
42 | from dual
43 | /
44 | select value inst_code1
45 | from v$parameter&inst_1
46 | where name = 'db_name'
47 | /
48 | select value inst_code2
49 | from v$parameter&inst_2
50 | where name = 'db_name'
51 | /
52 | set feedback on
53 | set heading on
54 | set newpage 0
55 |
56 |
57 | ttitle left 'OBJDIFF'-
58 | col 25 'OBJECT DIFFERENCE REPORT' -
59 | col 53 'Report Date: ' datetime -
60 | skip 1 col 60 'Page: ' sql.pno -
61 | skip 1 col 10 'OWNER: ' obj_owner -
62 | skip 1 center 'Objects in &inst_code1 but not &inst_code2' -
63 | skip 2
64 |
65 | set null=0
66 |
67 | column object_type format a15 heading 'Object Type';
68 | column object_name format a35 heading 'Object Name';
69 | column status format a10 heading 'Status';
70 | column inst_code format a10 heading 'Instance';
71 | select object_name, object_type, status
72 | from all_objects&inst_1
73 | where owner = UPPER('&obj_owner')
74 | -- and object_type != 'SYNONYM'
75 | MINUS
76 | select object_name, object_type, status
77 | from all_objects&inst_2
78 | where owner = UPPER('&obj_owner')
79 | -- and object_type != 'SYNONYM'
80 | order by 2,3
81 | /
82 | set heading off;
83 | set feedback off;
84 | select '' from dual
85 | /
86 | set heading on;
87 | set feedback on;
88 | ttitle left 'OBJDIFF'-
89 | col 25 'OBJECT DIFFERENCE REPORT' -
90 | col 53 'Report Date: ' datetime -
91 | skip 1 col 60 'Page: ' sql.pno -
92 | skip 1 col 10 'OWNER: ' obj_owner -
93 | skip 1 center 'Objects in &inst_code2 but not &inst_code1' -
94 | skip 2
95 |
96 | select object_name, object_type, status
97 | from all_objects&inst_2
98 | where owner = UPPER('&obj_owner')
99 | and object_type != 'SYNONYM'
100 | MINUS
101 | select object_name, object_type, status
102 | from all_objects&inst_1
103 | where owner = UPPER('&obj_owner')
104 | and object_type != 'SYNONYM'
105 | order by 2,3
106 | /
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/RecRefCons.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 |
4 | April 9, 1998
5 |
6 | Recreating Referential Constraints that Refer to a Table
7 | This Code Depot entry comes from Duncan Berriman, a Oracle DBA in Hessle, East Yorkshire, England.
8 |
9 | This script produces a script to re-create all the referential constraints that refer to a table.
10 | When you drop a table you must drop the referential constraints on all the other tables in the database
11 | that refer to the table you are trying to drop, or use the cascade constraints qualifier.
12 |
13 | Using this script you can export a table, drop it, re-import it and re-create the constraints.
14 | It's useful for deframenting a table or moving a table to another tablespace.
15 |
16 | */
17 |
18 | rem
19 | rem Procedure Recreate_ref_constraints.sql
20 | rem
21 | rem Description This SQL script generates referential constraints
22 | rem for a table.
23 | rem
24 | rem Argument(s) Table name
25 | rem
26 | rem Author Duncan Berriman, 1/4/98
27 | rem Duncan@dcl.co.uk
28 | rem http://www.dcl.co.uk/
29 |
30 | SPOOL &nome_file..ref
31 | SET PAGESIZE 0
32 | SET FEEDBACK OFF
33 | SET ECHO OFF
34 | SET VERIFY OFF
35 | SET LINESIZE 132
36 | COLUMN DUMMY_1 NOPRINT FORMAT A30
37 | COLUMN DUMMY_2 NOPRINT FORMAT 9
38 | COLUMN DUMMY_3 NOPRINT FORMAT 99
39 | COLUMN COMMAND FORMAT A80
40 |
41 | SELECT 'ALTER TABLE '||C.TABLE_NAME||' ADD CONSTRAINT '||
42 | C.CONSTRAINT_NAME||' FOREIGN KEY (' COMMAND,
43 | C.CONSTRAINT_NAME DUMMY_1, 1 DUMMY_2, 0 DUMMY_3
44 | FROM SYS.DBA_CONSTRAINTS C,SYS.DBA_INDEXES I
45 | WHERE I.TABLE_NAME = UPPER('&&nome_tabella')
46 | AND C.R_CONSTRAINT_NAME = I.INDEX_NAME
47 | AND C.CONSTRAINT_NAME IN (SELECT CONSTRAINT_NAME FROM SYS.DBA_CONSTRAINTS
48 | WHERE CONSTRAINT_TYPE = 'R')
49 | UNION
50 | SELECT DECODE(CC.POSITION,1,NULL,',') || CC.COLUMN_NAME COMMAND,
51 | CC.CONSTRAINT_NAME DUMMY_1, 2 DUMMY_2, CC.POSITION DUMMY_3
52 | FROM SYS.DBA_CONS_COLUMNS CC,SYS.DBA_CONSTRAINTS C, SYS.DBA_INDEXES I
53 | WHERE I.TABLE_NAME = UPPER('&&nome_tabella')
54 | AND C.R_CONSTRAINT_NAME = I.INDEX_NAME
55 | AND CC.CONSTRAINT_NAME = C.CONSTRAINT_NAME
56 | AND CC.CONSTRAINT_NAME IN (SELECT CONSTRAINT_NAME FROM SYS.DBA_CONSTRAINTS
57 | WHERE CONSTRAINT_TYPE = 'R')
58 | UNION
59 | SELECT ') REFERENCES '||I.TABLE_NAME||' (' COMMAND,
60 | C.CONSTRAINT_NAME DUMMY_1, 3 DUMMY_2, 0 DUMMY_3
61 | FROM SYS.DBA_INDEXES I, SYS.DBA_CONSTRAINTS C
62 | WHERE I.TABLE_NAME = UPPER('&&nome_tabella')
63 | AND C.R_CONSTRAINT_NAME = I.INDEX_NAME
64 | AND CONSTRAINT_NAME IN (SELECT CONSTRAINT_NAME FROM SYS.DBA_CONSTRAINTS
65 | WHERE CONSTRAINT_TYPE = 'R')
66 | UNION
67 | SELECT DECODE(IC.COLUMN_POSITION,1,NULL,',') || IC.COLUMN_NAME COMMAND,
68 | C.CONSTRAINT_NAME DUMMY_1, 4 DUMMY_2,IC.COLUMN_POSITION DUMMY_3
69 | FROM SYS.DBA_IND_COLUMNS IC, SYS.DBA_CONSTRAINTS C,SYS.DBA_INDEXES I
70 | WHERE I.TABLE_NAME = UPPER('&&nome_tabella')
71 | AND C.R_CONSTRAINT_NAME = I.INDEX_NAME
72 | AND IC.INDEX_NAME = I.INDEX_NAME
73 | AND C.CONSTRAINT_NAME IN (SELECT CONSTRAINT_NAME FROM SYS.DBA_CONSTRAINTS
74 | WHERE CONSTRAINT_TYPE = 'R')
75 | UNION
76 | SELECT ')'||DECODE(C.DELETE_RULE,'CASCADE',' ON DELETE CASCADE',NULL)||
77 | DECODE(C.STATUS,'DISABLED',' DISABLE',NULL)||';' COMMAND,
78 | C.CONSTRAINT_NAME DUMMY_1 ,5 DUMMY_2, 0 DUMMY_3
79 | FROM SYS.DBA_CONSTRAINTS C, SYS.DBA_INDEXES I
80 | WHERE I.TABLE_NAME = UPPER('&&nome_tabella')
81 | AND C.R_CONSTRAINT_NAME = I.INDEX_NAME
82 | AND CONSTRAINT_NAME IN (SELECT CONSTRAINT_NAME FROM SYS.DBA_CONSTRAINTS
83 | WHERE CONSTRAINT_TYPE = 'R')
84 | ORDER BY 2,3,4;
85 | SPOOL OFF
86 |
87 |
88 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/TABDIFF.SQL:
--------------------------------------------------------------------------------
1 | /*************************************************************************/
2 | /* tabdiff.sql - Lists the differences in table definitions in the tables*/
3 | /* for a schema in two different instances. Uses database*/
4 | /* links and the SQL MINUS operator to make the comparison.*/
5 | /* */
6 | /* Author: Ken Atkins (katkins@cco.net) */
7 | /* http://www.cco.net/~katkins/oratip */
8 | /* */
9 | /* Written: 5/11/95 */
10 | /* */
11 | /* You need to have a database link setup for any instance that you want */
12 | /* to make a comparison for. */
13 | /* */
14 | /* Please feel free to use and modify this script as long it is not sold */
15 | /* or included in any software without the prior permission of the author*/
16 | /* If you do make some good improvements, please send them to me, and I */
17 | /* can incorporate them in a future version and make them available to */
18 | /* others (giving you credit of course!). */
19 | /* */
20 | /*************************************************************************/
21 | set pagesize 60
22 | set linesize 105
23 | set verify off
24 | set feedback off
25 | set pause off;
26 |
27 | --define obj_owner = '&1'
28 | --define inst_1 = '&2'
29 | --define inst_2 = '&3'
30 | accept obj_owner prompt 'Table Owner: '
31 | accept inst_1 prompt 'First instance DB Link (Include @):'
32 | accept inst_2 prompt 'Second instance DB Link (Include @):'
33 |
34 | clear breaks
35 | ttitle off
36 | set heading off
37 |
38 | column datetime noprint new_value datetime
39 | column inst_code1 noprint new_value inst_code1
40 | column inst_code2 noprint new_value inst_code2
41 |
42 | select to_char(sysdate,'MM/DD/YY') datetime
43 | from dual
44 | /
45 | select value inst_code1
46 | from v$parameter&inst_1
47 | where name = 'db_name'
48 | /
49 | select value inst_code2
50 | from v$parameter&inst_2
51 | where name = 'db_name'
52 | /
53 | set feedback on
54 | set heading on
55 | set newpage 0
56 |
57 |
58 | ttitle left 'TABDIFF'-
59 | col 25 'SCHEMA DIFFERENCE REPORT' -
60 | col 53 'Report Date: ' datetime -
61 | skip 1 col 60 'Page: ' sql.pno -
62 | skip 1 col 10 'OWNER: ' obj_owner -
63 | skip 1 center 'Differences between &inst_code1 and &inst_code2' -
64 | skip 2
65 |
66 |
67 | column table_name format a25 heading 'Table';
68 | column column_name format a25 heading 'Column';
69 | column data_type format a8 heading 'DataType';
70 | column data_length format 999 heading 'Len';
71 | column data_precision format 999 heading 'Pr';
72 | column nullable format a5 heading 'Null?';
73 | column inst_code format a8 heading 'Instance';
74 | (
75 | select '&inst_code1' inst_code, table_name, column_name, data_type, data_length, data_precision, nullable
76 | from all_tab_columns&inst_1
77 | where owner = UPPER('&obj_owner')
78 | and table_name in (select table_name from all_tables&inst_2
79 | where owner = UPPER('&obj_owner'))
80 | MINUS
81 | select '&inst_code1' inst_code, table_name, column_name, data_type, data_length, data_precision, nullable
82 | from all_tab_columns&inst_2
83 | where owner = UPPER('&obj_owner')
84 | )
85 | UNION
86 | (
87 | select '&inst_code2' inst_code, table_name, column_name, data_type, data_length, data_precision, nullable
88 | from all_tab_columns&inst_2
89 | where owner = UPPER('&obj_owner')
90 | and table_name in (select table_name from all_tables&inst_1
91 | where owner = UPPER('&obj_owner'))
92 | MINUS
93 | select '&inst_code2' inst_code, table_name, column_name, data_type, data_length, data_precision, nullable
94 | from all_tab_columns&inst_1
95 | where owner = UPPER('&obj_owner')
96 | )
97 | order by 2, 3
98 | /
99 | undefine datetime
100 | undefine inst_code1
101 | undefine inst_code2
102 | undefine obj_owner
103 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/TModiUser.sql:
--------------------------------------------------------------------------------
1 | /**********************************************************************
2 | Copyright ESA Software SpA. Via Draghi, 39 RIMINI
3 | **********************************************************************
4 | *** Modulo : AMBIENTE
5 | *** RDBMS : Oracle
6 | *** Data : 05/10/98
7 | *** Autore : Stefano Teodorani
8 | *** Descrizione : Modifica lo user di un db importato da una sorgente
9 | *** con nome diverso
10 | **********************************************************************/
11 |
12 | -- da eseguire sol societario
13 | ALTER TABLE MGXX_MODULOUTE DISABLE CONSTRAINT MGXX_MODULOUTE_F2;
14 | ALTER TABLE MGXX_CONTRSTDOC DISABLE CONSTRAINT MGXX_CONTRSTDOC_F1;
15 | ALTER TABLE MGXX_CONTRSTDOC DISABLE CONSTRAINT MGXX_CONTRSTDOC_F2;
16 | ALTER TABLE CCXX_CONTRSTUTE DISABLE CONSTRAINT CCXX_CONTRSTUTE_F2;
17 | ALTER TABLE CCXX_CONTUTERIGA DISABLE CONSTRAINT CCXX_CONTUTERIGA_F2;
18 | ALTER TABLE CLXX_PAR_UTE disable constraint CLXX_PAR_UTE_F2;
19 | ALTER TABLE DBXX_PAR_UTE disable constraint DBXX_PAR_UTE_F2;
20 | ALTER TABLE PRXX_ST_MODUTE disable constraint PRXX_ST_MODUTE_F2;
21 |
22 |
23 | -- da eseguire sol sovrasocietario
24 | ACCEPT NUOVO_UTENTE CHAR PROMPT 'NUOVO UTENTE: '
25 | ACCEPT VECCHIO_UTENTE CHAR PROMPT 'VECCHIO UTENTE: '
26 |
27 | ALTER TABLE TSUM_SOCIETA DISABLE CONSTRAINT TSUM_SOCIETA_F1;
28 | ALTER TABLE TSUM_SOCIETA DISABLE CONSTRAINT TSUM_SOCIETA_F2;
29 | ALTER TABLE TSUM_UTEAPPLSOC DISABLE CONSTRAINT TSUM_UTEAPPLSOC_F1;
30 | ALTER TABLE TSUM_UTEAPPLSOC DISABLE CONSTRAINT TSUM_UTEAPPLSOC_F2;
31 | ALTER TABLE TSUM_UTEAPPLSOC DISABLE CONSTRAINT TSUM_UTEAPPLSOC_F3;
32 | ALTER TABLE TSUM_UTEAPPLSOCRUO DISABLE CONSTRAINT TSUM_UTEAPPLSOCRUO_F1;
33 | ALTER TABLE TSUM_UTEAPPLSOCRUO DISABLE CONSTRAINT TSUM_UTEAPPLSOCRUO_F2;
34 |
35 |
36 | UPDATE TSUM_UTENTEDB
37 | SET CDA_UTE_DB = '&NUOVO_UTENTE',
38 | DES_PWD_DB = '&NUOVO_UTENTE'
39 | WHERE CDA_UTE_DB = '&VECCHIO_UTENTE'
40 | /
41 |
42 | UPDATE TSUM_SOCIETA
43 | SET CDA_UTE_DB = '&NUOVO_UTENTE'
44 | WHERE CDA_UTE_DB = '&VECCHIO_UTENTE'
45 | /
46 |
47 | UPDATE TSUM_UTEAPPLSOC
48 | SET CDA_UTE_APPL = '&NUOVO_UTENTE',
49 | CDA_UTE_DB = '&NUOVO_UTENTE'
50 | WHERE CDA_UTE_DB = '&VECCHIO_UTENTE'
51 | /
52 |
53 | UPDATE TSUM_UTENTEAPPL
54 | SET CDA_UTE_APPL = '&NUOVO_UTENTE',
55 | DES_PWD_APPL = '&NUOVO_UTENTE'
56 | WHERE CDA_UTE_APPL = '&VECCHIO_UTENTE'
57 | /
58 |
59 | update TSUM_UTEAPPLSOCRUO
60 | SET CDA_UTE_APPL = '&NUOVO_UTENTE'
61 | WHERE CDA_UTE_APPL = '&VECCHIO_UTENTE'
62 | /
63 |
64 |
65 | ALTER TABLE TSUM_SOCIETA ENABLE CONSTRAINT TSUM_SOCIETA_F1;
66 | ALTER TABLE TSUM_SOCIETA ENABLE CONSTRAINT TSUM_SOCIETA_F2;
67 | ALTER TABLE TSUM_UTEAPPLSOC ENABLE CONSTRAINT TSUM_UTEAPPLSOC_F1;
68 | ALTER TABLE TSUM_UTEAPPLSOC ENABLE CONSTRAINT TSUM_UTEAPPLSOC_F2;
69 | ALTER TABLE TSUM_UTEAPPLSOC ENABLE CONSTRAINT TSUM_UTEAPPLSOC_F3;
70 | ALTER TABLE TSUM_UTEAPPLSOCRUO ENABLE CONSTRAINT TSUM_UTEAPPLSOCRUO_F1;
71 | ALTER TABLE TSUM_UTEAPPLSOCRUO ENABLE CONSTRAINT TSUM_UTEAPPLSOCRUO_F2;
72 |
73 |
74 | PAUSE FERMARE QUI ESECUZIONE
75 | -- SUL societario eseguire i seguenti update
76 |
77 |
78 | UPDATE MGXX_MODULOUTE
79 | SET CDA_UTE_APPL = '&NUOVO_UTENTE'
80 | WHERE CDA_UTE_APPL = '&VECCHIO_UTENTE'
81 | /
82 |
83 | UPDATE CCXX_CONTRSTUTE
84 | SET CDA_UTE_APPL = '&NUOVO_UTENTE'
85 | WHERE CDA_UTE_APPL = '&VECCHIO_UTENTE'
86 | /
87 |
88 | UPDATE MGXX_CONTRSTDOC
89 | SET CDA_UTE_APPL = '&NUOVO_UTENTE'
90 | WHERE CDA_UTE_APPL = '&VECCHIO_UTENTE'
91 | /
92 |
93 | ALTER TABLE MGXX_MODULOUTE ENABLE CONSTRAINT MGXX_MODULOUTE_F2;
94 | ALTER TABLE MGXX_CONTRSTDOC ENABLE CONSTRAINT MGXX_CONTRSTDOC_F1;
95 | ALTER TABLE MGXX_CONTRSTDOC ENABLE CONSTRAINT MGXX_CONTRSTDOC_F2;
96 | ALTER TABLE CCXX_CONTRSTUTE ENABLE CONSTRAINT CCXX_CONTRSTUTE_F2;
97 | ALTER TABLE CCXX_CONTUTERIGA ENABLE CONSTRAINT CCXX_CONTUTERIGA_F2;
98 | ALTER TABLE CLXX_PAR_UTE enable constraint CLXX_PAR_UTE_F2;
99 | ALTER TABLE DBXX_PAR_UTE enable constraint DBXX_PAR_UTE_F2;
100 | ALTER TABLE PRXX_ST_MODUTE enable constraint PRXX_ST_MODUTE_F2;
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/TrigInfo.sql:
--------------------------------------------------------------------------------
1 | /*
2 | BIJU'S ORACLE PAGE
3 |
4 | triginfo.sql
5 |
6 | Purpose
7 |
8 | Body of Trigger in parameter. Wild characters may be used (%) in the parameter list.Screen output saved at /tmp/triginfo.lst
9 |
10 | Parameters
11 |
12 | 1. Trigger Owner (Wild character % may be used)
13 | 2. Trigger Name (Wild character % may be used)
14 | Command Line
15 |
16 | SQL> @triginfo scott %
17 |
18 | The Script
19 | */
20 | rem
21 | rem Trigger text
22 | rem
23 | rem Input : Trigger owner and name
24 | rem
25 | rem Biju Thomas
26 | rem
27 | set pages 0 feedback off lines 200 trims on echo off long 32000 verify off
28 | spool c:\temp\triginfo.lst
29 | select DESCRIPTION, trigger_body
30 | from all_triggers
31 | where owner like upper('&1')
32 | and trigger_name like upper('&2')
33 | /
34 | spool off
35 | set pages 24 feedback on lines 80 trims on verify on
36 | prompt
37 | prompt Output saved at c:\temp\triginfo.lst
38 | prompt
39 | Example Output
40 | before_update_dept
41 | before update of dname on dept for each row
42 | begin
43 | if :old.dname = 'CORPORATE' and :old.deptno = 10 then
44 | :new.dname = 'CORPORATE';
45 | end if;
46 | end;
47 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/gen_.txt:
--------------------------------------------------------------------------------
1 | README for MNTCONS.EXE
2 |
3 | This ZIP file contains two SQL*Plus scripts you can edit to taste.
4 | Each generates 2 SQL*Plus scripts for maintainting Constraints
5 | within the logged-into schema.
6 |
7 |
8 | GEN_ABLE.SQL - Generates file C:\CON_DIS.SQL to DISABLE all
9 | FK, PK and UNIQUE constraints in the schem, in
10 | that order.
11 | - Then generates file C:\CONS_EN to ENABLE all
12 | the same constraints in reverse order.
13 |
14 |
15 | Running the first allows loading data into the schema.
16 | Run the second once that is done to restore the
17 | constraints.
18 |
19 | To alter tables, however, FK constraints must be dropped.
20 |
21 |
22 | GEN_DCON.SQL - Generates file C:\CON_DROP.SQL. Running CON_DROP.SQL
23 | DROPs all FK, then PK and UNIQUE constraints in the
24 | schema.
25 | - Generates file C:\CON_CR.SQL, which, when run, re-creates
26 | all the same constraints in revers order. It takes a
27 | long time for this return set to generate, so be patient.
28 | - The generated CREATEs do not include the constraints'
29 | USING INDEX or EXCEPTONS INTO clauses.
30 |
31 |
32 |
33 | Keith McLeod
34 | Deliberate Creations Inc.
35 | 2 Bloor St. W. #100
36 | Toronto, Ont.
37 | M4W 3E2
38 | keithmcleod@compuserve.com
39 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/Teo/gen_able.sql:
--------------------------------------------------------------------------------
1 | /*
2 | / GEN_ABLE
3 | / -------- Keith McLeod
4 | / 96/10/4
5 | / Create scripts to DISABLE and ENABLE all FK, PK
6 | / and UNIQUE constraints in the executed-in schema.
7 | /
8 | / Disable FKs first, then PKs and Unique. *En*able
9 | / in reverse order.
10 | */
11 |
12 |
13 | set feed off sqln off sqlp ' '
14 | set pause off hea off echo off pages 0
15 | set termout on timing off
16 |
17 |
18 | -- ** DISable **
19 |
20 | spool c:\con_dis.sql
21 | -- FKs first.
22 | select
23 | 'alter table '
24 | || table_name
25 | || ' disable constraint '
26 | || constraint_name
27 | || ';'
28 | from
29 | user_constraints
30 | where
31 | constraint_type = 'R'
32 | order by
33 | table_name,
34 | constraint_name
35 | ;
36 | -- PKs and UNIQUE.
37 | select
38 | 'alter table '
39 | || table_name
40 | || ' disable constraint '
41 | || constraint_name
42 | || ';'
43 | from
44 | user_constraints
45 | where
46 | constraint_type in( 'P', 'U' )
47 | order by
48 | table_name,
49 | constraint_name
50 | ;
51 |
52 |
53 |
54 |
55 |
56 | -- ** ENable **
57 |
58 | spool off
59 | spool c:\con_en.sql
60 | -- PKs and UNIQUE first.
61 | select
62 | 'alter table '
63 | || table_name
64 | || ' enable constraint '
65 | || constraint_name
66 | || ';'
67 | from
68 | user_constraints
69 | where
70 | constraint_type in( 'P', 'U' )
71 | order by
72 | table_name,
73 | constraint_name
74 | ;
75 | -- FKs.
76 | select
77 | 'alter table '
78 | || table_name
79 | || ' enable constraint '
80 | || constraint_name
81 | || ';'
82 | from
83 | user_constraints
84 | where
85 | constraint_type = 'R'
86 | order by
87 | table_name,
88 | constraint_name
89 | ;
90 |
91 | spool off
92 | set feed on sqln on sqlp 'SQL>'
93 | set pause on hea on echo on
94 | set termout on timing on pages 40
95 |
--------------------------------------------------------------------------------
/Script/To Verify/Tools/fk_splitted.sql:
--------------------------------------------------------------------------------
1 | -- Creazione tabella temporanea
2 | -- ----------------------------
3 | create table test
4 | as
5 | select column_name, constraint_name , table_name from user_cons_columns
6 | where constraint_name in (select constraint_name from user_constraints where constraint_type = 'R')
7 | ;
8 |
9 | -- Aggiunta campo della nome pk relativa
10 | -- -------------------------------------
11 | alter table test add (pkname varchar(30));
12 |
13 | -- Aggiunta campo flag di pk
14 | -- -------------------------
15 | alter table test add (pkflag number(1));
16 |
17 | -- Rimuovo le fk con un solo campo
18 | -- -------------------------------
19 | BEGIN
20 | LOOP
21 | DELETE FROM test
22 | WHERE ROWID IN (SELECT MIN (ROWID)
23 | FROM test
24 | GROUP BY constraint_name
25 | HAVING COUNT (*) = 1);
26 | EXIT WHEN SQL%NOTFOUND;
27 | END LOOP;
28 | COMMIT;
29 | END;
30 | /
31 |
32 | --- --------------
33 |
34 | -- Aggiunge il nome della pk
35 |
36 | declare
37 | v_table_name varchar2(30);
38 | v_column_name varchar2(30);
39 | v_constraint_name varchar2(30);
40 | v_pkname varchar2(30);
41 | ispk number(30);
42 |
43 | cursor c1 is
44 | select column_name, table_name, constraint_name
45 | from test;
46 |
47 | begin
48 |
49 | open c1;
50 | loop
51 | fetch c1 into v_column_name, v_table_name, v_constraint_name;
52 | exit when c1%NOTFOUND;
53 | begin
54 | select constraint_name into v_pkname
55 | from user_constraints
56 | where constraint_type = 'P'
57 | and table_name = v_table_name;
58 |
59 | update test
60 | set pkname = v_pkname
61 | where table_name = v_table_name;
62 |
63 | --dbms_output.put_line(v_pkname ||'-'||v_table_name);
64 | end;
65 | end loop;
66 | close c1;
67 | end;
68 | /
69 |
70 | -- -------------------
71 |
72 | -- aggiornamento flag di pk
73 | set serveroutput on
74 | declare
75 | v_table_name varchar2(30);
76 | v_column_name varchar2(30);
77 | v_constraint_name varchar2(30);
78 | v_pkname varchar2(30);
79 | ispk number(30);
80 |
81 | cursor c1 is
82 | select column_name, table_name, constraint_name, pkname
83 | from test
84 | ;
85 |
86 | begin
87 | dbms_output.enable(1000000);
88 | open c1;
89 | loop
90 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname;
91 | exit when c1%NOTFOUND;
92 | begin
93 | update test a
94 | set a.pkflag = 1
95 | where a.table_name = v_table_name
96 | and a.column_name in (
97 | select column_name
98 | from user_cons_columns
99 | where constraint_name = v_pkname
100 | and table_name = v_table_name
101 | )
102 | ;
103 | -- dbms_output.put_line(v_column_name||' - '||v_table_name||' - '||v_pkname);
104 | end;
105 | end loop;
106 | close c1;
107 | end;
108 | /
109 |
110 |
111 | -- report
112 | set serveroutput on
113 | declare
114 | v_table_name varchar2(30);
115 | v_column_name varchar2(30);
116 | v_constraint_name varchar2(30);
117 | v_pkname varchar2(30);
118 | v_pkflag number(1);
119 | v_total_rows number(30);
120 | v_pk_rows number(30);
121 | v_no_pk_rows number(30);
122 | a number(1);
123 |
124 | cursor c1 is
125 | select column_name, table_name, constraint_name, pkname, pkflag
126 | from test
127 | ;
128 |
129 | begin
130 | dbms_output.enable(1000000);
131 | open c1;
132 | loop
133 | fetch c1 into v_column_name, v_table_name, v_constraint_name, v_pkname, v_pkflag;
134 | exit when c1%NOTFOUND;
135 | begin
136 | select count(*) into v_total_rows
137 | from test
138 | where constraint_name = v_constraint_name;
139 |
140 | select count(*) into v_pk_rows
141 | from test
142 | where constraint_name = v_constraint_name
143 | and pkflag is not null;
144 |
145 | select count(*) into v_no_pk_rows
146 | from test
147 | where constraint_name = v_constraint_name
148 | and pkflag is null;
149 |
150 | if (v_total_rows = v_pk_rows) or (v_total_rows = v_no_pk_rows) then
151 | a := 0;
152 | else
153 | dbms_output.put_line('FK Name: '||v_constraint_name ||', '|| 'No.of fields:'||v_total_rows||', '||'PK Fields:'|| v_pk_rows||', '||'No key fields:'|| v_no_pk_rows);
154 | end if;
155 | end;
156 | end loop;
157 | close c1;
158 | end;
159 | /
160 |
161 | drop table test;
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/CheckCheck.sql:
--------------------------------------------------------------------------------
1 | rem
2 | rem CheckCheck.sql
3 | rem ----------------
4 | rem Ultima revisione:
5 | rem r2.1 del 17/09/99
6 | rem r2.2 del 24/01/2001, S. Teodorani - Aggiunta clausola CASCADE CONSTRAINT in DROP TABELLA
7 | rem Aggiuto elenco delle colonne nello statement di insert
8 | rem Descrizione:
9 | rem Ricostruzione degli statements necessari per rigenerare una tabella.
10 | rem Input:
11 | rem Nome della Tabella
12 | rem Output:
13 | rem Script c:\temp\GenFix.txt
14 | rem Nota:
15 | rem Deve esistere la directory C:\Temp
16 | rem
17 |
18 | undef tab;
19 | set echo off
20 |
21 | set pages 0 feed off verify off lines 150 trims on
22 | col c1 format a80
23 |
24 | set serveroutput on
25 | spool c:\temp\CheckCheck.txt
26 |
27 | prompt Please Wait...
28 |
29 | /* Reverse dei check constraints */
30 | /* ----------------------------- */
31 | declare
32 | cursor c1 is
33 | select constraint_name a2,
34 | search_condition a3,
35 | table_name a4
36 | from user_constraints
37 | where constraint_type='C';
38 | b1 varchar2(100);
39 | b2 varchar2(100);
40 | b3 varchar2(32000);
41 | b4 varchar2(100);
42 | b5 varchar2(100);
43 | extcheck varchar2(200);
44 | fl number;
45 | ck1 number;
46 | ck2 number;
47 | begin
48 | dbms_output.enable(999999);
49 | open c1;
50 | loop
51 | fetch c1 into b2,b3,b4;
52 | exit when c1%NOTFOUND;
53 | select count(*) into fl
54 | from user_tab_columns
55 | where table_name = b4
56 | and (
57 | upper(column_name)||' IS NOT NULL' = upper(b3)
58 | or
59 | '"' || upper(column_name)||'" IS NOT NULL' = upper(b3)
60 | );
61 |
62 | if fl = 0 then
63 | extcheck := substr(b2,instr(b2, '_E', -1)+1);
64 |
65 | -- dbms_output.put_line('constraint='||b2);
66 | -- dbms_output.put_line('table='||b4);
67 | -- dbms_output.put_line('id='||extcheck);
68 |
69 | select count(*) into ck1
70 | from ts_tableid
71 | where table_name = b4;
72 | if ck1 = 0 then
73 | dbms_output.put_line('Riferimento TABLE_NAME mancante sulla TS_TABLEID per la tabella '||b4);
74 | end if;
75 | select count(*) into ck2
76 | from ts_tableid
77 | where id = extcheck;
78 | if ck2 = 0 then
79 | dbms_output.put_line('Il check '|| b2 ||' non ha un ID sulla TS_TABLEID per la tabella '||b4);
80 | end if;
81 | end if;
82 | end loop;
83 | end;
84 | /
85 | spool off
86 | set echo on feed on verify on
87 |
88 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/Conntrolnew.sql:
--------------------------------------------------------------------------------
1 | set heading off
2 | set verify off
3 | set feedback off
4 | set show off
5 | set trim ON
6 | set pages 0
7 | set concat on
8 | spool &1..ctl
9 | SELECT
10 | 'OPTIONS(DIRECT=TRUE)'||chr(10)
11 | ||'LOAD DATA'||chr(10)
12 | ||'INFILE '''||lower(table_name)||'.dat'' '||chr(10)
13 | ||'INTO TABLE '||table_name||chr(10)
14 | ||'FIELDS TERMINATED BY ''|'' '||chr(10)
15 | ||'TRAILING NULLCOLS'||chr(10)
16 | ||'('
17 | FROM user_tables
18 | WHERE TABLE_NAME = UPPER('&1');
19 | SELECT DECODE(ROWNUM,1,' ',' , ')||RPAD(column_name,33,' ')
20 | ||DECODE(data_type,
21 | 'VARCHAR2', 'CHAR NULLIF('|| column_name ||'=BLANKS)',
22 | 'FLOAT', 'DECIMAL EXTERNAL NULLIF('||column_name||'=BLANKS)',
23 | 'NUMBER', decode(data_precision,
24 | 0, 'INTEGER EXTERNAL NULLIF ('||column_name||'=BLANKS)',
25 | decode(data_scale,
26 | 0, 'INTEGER EXTERNAL NULLIF ('||column_name ||'=BLANKS)',
27 | 'DECIMAL EXTERNAL NULLIF ('||column_name ||'=BLANKS)'
28 | )
29 | ),
30 | 'DATE', 'DATE "DD/MM/YYYY" NULLIF ('||column_name||'=BLANKS)',
31 | NULL)
32 | FROM
33 | user_tab_columns
34 | WHERE
35 | TABLE_NAME = UPPER('&1')
36 | ORDER BY
37 | COLUMN_ID;
38 |
39 | SELECT ')' FROM sys.dual;
40 |
41 | spool off
42 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/ControlDirect.sql:
--------------------------------------------------------------------------------
1 | REM control.sql script
2 |
3 | SET ECHO off
4 | REM REQUIREMENTS
5 | REM SELECT privileges on the table
6 | REM -------------------------------------------------------------------------- ----
7 | REM PURPOSE:
8 | REM Prepares a SQL*Loader control file for a table already existing in the
9 | REM database. The script accepts the table name and automatically creates
10 | REM a file with the table name and extension 'ctl'.
11 | REM This is especially useful if you have the DDL statement to create a
12 | REM particular table and have a free-format ASCII-delimited file but have
13 | REM not yet created a SQL*Loader control file for the loading operation.
14 | REM
15 | REM Default choices for the file are as follows (alter to your needs):
16 | REM Delimiter: comma (',')
17 | REM INFILE file extension: .dat
18 | REM DATE format: 'MM/DD/YY'
19 | REM
20 | REM You may define the Loader Data Types of the other Data Types by
21 | REM revising the decode function pertaining to them.
22 | REM
23 | REM ---------------------------------------------------------------------------
24 | REM EXAMPLE:
25 | REM SQL> start control.sql emp
26 | REM
27 | REM LOAD DATA
28 | REM INFILE 'EMP.dat'
29 | REM INTO TABLE EMP
30 | REM FIELDS TERMINATED BY ','
31 | REM (
32 | REM
33 | REM EMPNO
34 | REM , ENAME
35 | REM , JOB
36 | REM , MGR
37 | REM , HIREDATE DATE "DD/MM/YYYY"
38 | REM , SAL
39 | REM , COMM
40 | REM , DEPTNO
41 | REM
42 | REM )
43 | REM
44 | REM ---------------------------------------------------------------------------
45 | REM DISCLAIMER:
46 | REM This script is provided for educational purposes only. It is NOT
47 | REM supported by Oracle World Wide Technical Support.
48 | REM The script has been tested and appears to work as intended.
49 | REM You should always run new scripts on a test instance initially.
50 | REM --------------------------------------------------------------------------
51 | REM Main text of script follows:
52 |
53 | set heading off
54 | set verify off
55 | set feedback off
56 | set show off
57 | set trim off
58 | set pages 0
59 | set concat on
60 | spool &1..ctl
61 | SELECT
62 | 'OPTIONS(DIRECT=TRUE)'||chr(10)
63 | ||'LOAD DATA'||chr(10)
64 | ||'INFILE '''||lower(table_name)||'.dat'' '||chr(10)
65 | ||'INTO TABLE '||table_name||chr(10)
66 | ||'FIELDS TERMINATED BY ''|'' '||chr(10)
67 | ||'TRAILING NULLCOLS'||chr(10)
68 | ||'('
69 | FROM user_tables
70 | WHERE TABLE_NAME = UPPER('&1');
71 | SELECT decode(rownum,1,' ',' , ')||rpad(column_name,33,' ')
72 | || decode(data_type,
73 | 'VARCHAR2','CHAR NULLIF('|| column_name ||'=BLANKS)',
74 | 'FLOAT', 'DECIMAL EXTERNAL NULLIF('||column_name||'=BLANKS)',
75 | 'NUMBER',
76 | decode(data_precision,
77 | 0, 'INTEGER EXTERNAL NULLIF ('||column_name
78 | ||'=BLANKS)',
79 | decode(data_scale,0,
80 | 'INTEGER EXTERNAL NULLIF
81 | ('||column_name ||'=BLANKS)',
82 | 'DECIMAL EXTERNAL NULLIF
83 | ('||column_name ||'=BLANKS)'
84 | )
85 | ),
86 | 'DATE', 'DATE "DD/MM/YYYY" NULLIF ('||column_name
87 | ||'=BLANKS)',NULL)
88 | FROM user_tab_columns
89 | WHERE TABLE_NAME = UPPER('&1')
90 | ORDER BY COLUMN_ID;
91 | SELECT ')'
92 | FROM sys.dual;
93 | spool off
94 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/FKListToFrom.SQL:
--------------------------------------------------------------------------------
1 | rem ===================================================
2 | rem FkTable.sql
3 | rem -----------
4 | rem Ultima revisione:
5 | rem r1.0 del 28/04/99
6 | rem
7 | rem Descrizione:
8 | rem Ricostruzione della Foreign key indicata
9 | rem come parametro.
10 | rem
11 | rem Parametri:
12 | rem 1. Nome Foreign key
13 | rem ===================================================
14 |
15 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
16 |
17 | set serveroutput on verify off trims on feedback off linesize 255 termout on
18 |
19 | /* *** Creazione delle Foreign Key ************************************************* */
20 |
21 | declare
22 |
23 | cname varchar2(50);
24 | cname2 varchar2(50);
25 | r_user varchar2(50);
26 |
27 | cursor c1 is
28 | select c.constraint_name,
29 | c.r_constraint_name cname2,
30 | c.table_name table1,
31 | r.table_name table2,
32 | decode(c.status,'DISABLED','DISABLE',' ') status,
33 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
34 | c.r_owner r_user
35 | from all_constraints c,
36 | all_constraints r
37 | where c.constraint_type='R'
38 | and c.r_constraint_name = r.constraint_name
39 | and c.table_name = upper('&nome_tabella')
40 | and c.owner = user
41 | and c.r_owner = r.owner
42 | union
43 | select c.constraint_name,c.r_constraint_name cname2,
44 | c.table_name table1, r.table_name table2,
45 | decode(c.status,'DISABLED','DISABLE',' ') status,
46 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
47 | c.r_owner r_user
48 | from user_constraints c,
49 | user_constraints r
50 | where c.constraint_type='R' and
51 | c.r_constraint_name = r.constraint_name and
52 | r.table_name = upper('&nome_tabella');
53 |
54 | cursor c2 is
55 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) colname
56 | from user_cons_columns
57 | where constraint_name = cname
58 | order by position;
59 |
60 | cursor c3 is
61 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) refcol
62 | from all_cons_columns
63 | where constraint_name = cname2
64 | and owner = r_user
65 | order by position;
66 |
67 | begin
68 | dbms_output.enable(999999);
69 | for q1 in c1 loop
70 | cname := q1.constraint_name;
71 | cname2 := q1.cname2;
72 | r_user := q1.r_user;
73 |
74 | dbms_output.put('alter table '||q1.table1||' add constraint '||cname||CHR(10)||' foreign key');
75 | for q2 in c2 loop
76 | dbms_output.put_line(q2.colname);
77 | end loop;
78 | dbms_output.put(') '||CHR(10)||' references '||q1.table2);
79 | for q3 in c3 loop
80 | dbms_output.put_line(q3.refcol);
81 | end loop;
82 | dbms_output.put(')'||q1.delete_rule||q1.status||';');
83 | dbms_output.put_line(chr(10));
84 | end loop;
85 | end;
86 | /
87 |
88 | set serveroutput off verify on trims off feedback on linesize 100 termout on;
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/Lockdtab.SQL:
--------------------------------------------------------------------------------
1 | REM lockdtab.sql
2 | REM Show tables being locked
3 | REM
4 | column Username format A15
5 | column Sid format 9990 heading SID
6 | column Type format A4
7 | column Lmode format 990 heading 'HELD'
8 | column Request format 990 heading 'REQ'
9 | column Id1 format 9999990
10 | column Id2 format 9999990
11 | column Owner format A20
12 | column Object format A32
13 | break on Id1 skip 1 dup
14 | select SN.Username,
15 | M.Sid,
16 | M.Type,
17 | A.Owner,
18 | A.Object,
19 | DECODE(M.Lmode, 0, 'None',
20 | 1, 'Null',
21 | 2, 'Row Share',
22 | 3, 'Row Excl.',
23 | 4, 'Share',
24 | 5, 'S/Row Excl.',
25 | 6, 'Exclusive',
26 | Lmode, LTRIM(TO_CHAR(Lmode,'990'))) Lmode,
27 | DECODE(M.Request, 0, 'None',
28 | 1, 'Null',
29 | 2, 'Row Share',
30 | 3, 'Row Excl.',
31 | 4, 'Share',
32 | 5, 'S/Row Excl.',
33 | 6, 'Exclusive',
34 | Request, LTRIM(TO_CHAR(M.Request,
35 | '990'))) Request,
36 | M.Id1, M.Id2
37 | from V$SESSION SN, V$LOCK M, V$ACCESS A
38 | where SN.Sid = A.Sid and A.Owner <> 'SYS'
39 | and a.owner = sn.sid
40 | and ((SN.Sid = M.Sid
41 | and M.Request != 0)
42 | or (SN.Sid = M.Sid
43 | and M.Request = 0 and Lmode != 4
44 | and (id1, id2) in
45 | (select S.Id1, S.Id2
46 | from V$LOCK S
47 | where Request != 0
48 | and S.Id1 = M.Id1
49 | and S.Id2 = M.Id2) ) )
50 | order by Id1, Id2, M.Request;
51 |
52 | clear breaks
53 | clear columns
54 |
55 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/RegenCheck.sql:
--------------------------------------------------------------------------------
1 | rem
2 | rem RegenCheck.sql
3 | rem ----------------
4 | rem Ultima revisione:
5 | rem r2.1 del 17/09/99
6 | rem r2.2 del 24/01/2001, S. Teodorani - Aggiunta clausola CASCADE CONSTRAINT in DROP TABELLA
7 | rem Aggiuto elenco delle colonne nello statement di insert
8 | rem Descrizione:
9 | rem Ricostruzione degli statements necessari per rigenerare una tabella.
10 | rem Input:
11 | rem Nome della Tabella
12 | rem Output:
13 | rem Script c:\temp\GenFix.txt
14 | rem Nota:
15 | rem Deve esistere la directory C:\Temp
16 | rem
17 |
18 | ACCEPT nome_tabella CHAR PROMPT 'Tabella: '
19 |
20 | undef tab;
21 | set echo off
22 |
23 | set pages 0 feed off verify off lines 150 trims on
24 | col c1 format a80
25 |
26 | spool c:\temp\RegenCheck.txt
27 |
28 | /* Reverse dei check constraints */
29 | /* ----------------------------- */
30 | declare
31 | cursor c1 is
32 | select 'exec esa.drop_fk('''|| constraint_name || ''')',
33 | search_condition a3
34 | from user_constraints
35 | where table_name = upper('&nome_tabella') and
36 | constraint_type='C';
37 | b1 varchar2(100);
38 | b3 varchar2(32000);
39 | fl number;
40 | begin
41 | dbms_output.enable(999999);
42 | open c1;
43 | loop
44 | fetch c1 into b1,b3;
45 | exit when c1%NOTFOUND;
46 | select count(*) into fl from user_tab_columns where table_name =
47 | upper('&nome_tabella')
48 | and (
49 | upper(column_name)||' IS NOT NULL' = upper(b3)
50 | or
51 | '"' || upper(column_name)||'" IS NOT NULL' = upper(b3)
52 | );
53 | if fl = 0 then
54 | dbms_output.put_line(b1);
55 | end if;
56 | end loop;
57 | end;
58 | /
59 |
60 | prompt
61 |
62 | /* Reverse dei check constraints */
63 | /* ----------------------------- */
64 | declare
65 | cursor c1 is
66 | select 'ALTER TABLE '||'&nome_tabella'||' ADD CONSTRAINT ' a1,
67 | constraint_name||CHR(10)||' CHECK (' a2,
68 | search_condition a3,
69 | ') '||decode(status,'DISABLED','DISABLE','') a4,
70 | ';'||CHR(10) a5
71 | from user_constraints
72 | where table_name = upper('&nome_tabella') and
73 | constraint_type='C';
74 | b1 varchar2(100);
75 | b2 varchar2(100);
76 | b3 varchar2(32000);
77 | b4 varchar2(100);
78 | b5 varchar2(100);
79 | fl number;
80 | begin
81 | dbms_output.enable(999999);
82 | open c1;
83 | loop
84 | fetch c1 into b1,b2,b3,b4,b5;
85 | exit when c1%NOTFOUND;
86 | select count(*) into fl from user_tab_columns where table_name =
87 | upper('&nome_tabella')
88 | and (
89 | upper(column_name)||' IS NOT NULL' = upper(b3)
90 | or
91 | '"' || upper(column_name)||'" IS NOT NULL' = upper(b3)
92 | );
93 | if fl = 0 then
94 | dbms_output.put(b1);
95 | dbms_output.put(ltrim(rtrim(b2)));
96 | dbms_output.put(ltrim(rtrim(b3)));
97 | dbms_output.put(ltrim(rtrim(b4)));
98 | dbms_output.put_line(ltrim(rtrim(b5)));
99 | end if;
100 | end loop;
101 | end;
102 | /
103 | spool off
104 | set echo on feed on verify on
105 |
106 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/ShowFK.SQL:
--------------------------------------------------------------------------------
1 | rem ===================================================
2 | rem FkTable.sql
3 | rem -----------
4 | rem Ultima revisione:
5 | rem r1.0 del 28/04/99
6 | rem
7 | rem Descrizione:
8 | rem Ricostruzione della Foreign key indicata
9 | rem come parametro.
10 | rem
11 | rem Parametri:
12 | rem 1. Nome Foreign key
13 | rem ===================================================
14 |
15 | ACCEPT nome_fk CHAR PROMPT 'Nome Foreign_key: '
16 |
17 | set serveroutput on verify off trims on feedback off linesize 255 termout on
18 |
19 | /* *** Creazione delle Foreign Key ************************************************* */
20 | prompt
21 |
22 | declare
23 |
24 | cname varchar2(50);
25 | cname2 varchar2(50);
26 | r_user varchar2(50);
27 |
28 | cursor c1 is
29 | select c.constraint_name,
30 | c.r_constraint_name cname2,
31 | c.table_name table1,
32 | r.table_name table2,
33 | decode(c.status,'DISABLED','DISABLE',' ') status,
34 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
35 | c.r_owner r_user
36 | from all_constraints c,
37 | all_constraints r
38 | where c.constraint_type='R'
39 | and c.r_constraint_name = r.constraint_name
40 | and c.owner = user
41 | and c.r_owner = r.owner
42 | and c.constraint_name like upper('&nome_fk%');
43 |
44 | cursor c2 is
45 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) colname
46 | from user_cons_columns
47 | where constraint_name = cname
48 | order by position;
49 |
50 | cursor c3 is
51 | select ltrim(rtrim(decode(position,1,'(',',')||rpad(column_name,40))) refcol
52 | from all_cons_columns
53 | where constraint_name = cname2
54 | and owner = r_user
55 | order by position;
56 |
57 | begin
58 | dbms_output.enable(999999);
59 | for q1 in c1 loop
60 | cname := q1.constraint_name;
61 | cname2 := q1.cname2;
62 | r_user := q1.r_user;
63 |
64 | dbms_output.put('alter table '||q1.table1||' add constraint '||cname||CHR(10)||' foreign key');
65 | for q2 in c2 loop
66 | dbms_output.put_line(q2.colname);
67 | end loop;
68 | dbms_output.put(') '||CHR(10)||' references '||q1.table2);
69 | for q3 in c3 loop
70 | dbms_output.put_line(q3.refcol);
71 | end loop;
72 | dbms_output.put(')'||q1.delete_rule||q1.status||';');
73 | dbms_output.put_line(chr(10));
74 | end loop;
75 | end;
76 | /
77 |
78 | set serveroutput off verify on trims off feedback on linesize 100 termout on;
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/TFSDTFRG.SQL:
--------------------------------------------------------------------------------
1 |
2 | SET ECHO off
3 | REM NAME: TFSDTFRG.SQL
4 | REM USAGE:"@path/tfsdtfrg"
5 | REM ------------------------------------------------------------------------
6 | REM REQUIREMENTS:
7 | REM SELECT on TFRAG table created by TFSLDTFR.SQL
8 | REM ------------------------------------------------------------------------
9 | REM AUTHOR:
10 | REM Craig A. Shallahamer, Oracle US
11 | REM ------------------------------------------------------------------------
12 | REM PURPOSE:
13 | REM Detailed report of table fragmentation characteristics based on the
14 | REM data in the tfrag table.
15 | REM ------------------------------------------------------------------------
16 | REM EXAMPLE:
17 | REM Detailed Table Fragmentation Characteristics
18 | REM
19 | REM
20 | REM Table Owner : scott
21 | REM Name : s_emp
22 | REM Extents : 1
23 | REM High water mark : 1
24 | REM Blocks with rows : 1
25 | REM Block frag: Omega1 : 0
26 | REM Migrated rows : 0
27 | REM
28 | REM ------------------------------------------------------------------------
29 | REM DISCLAIMER:
30 | REM This script is provided for educational purposes only. It is NOT
31 | REM supported by Oracle World Wide Technical Support.
32 | REM The script has been tested and appears to work as intended.
33 | REM You should always run new scripts on a test instance initially.
34 | REM ------------------------------------------------------------------------
35 | REM Main text of script follows:
36 |
37 | col towner format a70
38 | col tname format a70
39 | col exts format 999
40 | col omega1 format 90.9999
41 | col chains format 99,990
42 | col rpb format 999
43 | col hwm format 9,999,999
44 | col bwr format 9,999,999
45 |
46 | ttitle -
47 | center 'Detailed Table Fragmentation Characteristics' skip 2
48 |
49 | set heading off
50 |
51 | select 'Table Owner : '||owner towner,
52 | ' Name : '||name tname,
53 | 'Extents : '||no_extents exts,
54 | 'High water mark : '||hwm hwm,
55 | 'Blocks with rows : '||blks_w_rows bwr,
56 | 'Block frag: Omega1 : '||(hwm - blks_w_rows)/(hwm + 0.0001) omega1,
57 | 'Migrated rows : '||no_frag_rows chains
58 | from tfrag
59 | order by 1,2
60 | /
61 |
62 | set heading on
63 |
64 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/TFSTFRAG.SQL:
--------------------------------------------------------------------------------
1 |
2 | SET ECHO off
3 | REM NAME: TFSTFRAG.SQL
4 | REM USAGE:"@path/tfstfrag"
5 | REM ------------------------------------------------------------------------
6 | REM REQUIREMENTS:
7 | REM SELECT on TFRAG
8 | REM ------------------------------------------------------------------------
9 | REM AUTHOR:
10 | REM Craig A. Shallahamer, Oracle USA
11 | REM ------------------------------------------------------------------------
12 | REM PURPOSE:
13 | REM This script displays summary table fragmentation information. The
14 | REM information is queried from the tfrag table which is loaded via the
15 | REM ldtfrag script. Once the ldtfrag script has been run for a given
16 | REM table, this report displays the following information:
17 | REM
18 | REM - Table owner
19 | REM - Table name
20 | REM - Segment fragmentation (number of extents)
21 | REM - Number of table rows
22 | REM - Table block fragmentation (1.0 bad, 0.0 good)
23 | REM - Row fragmentation (chains)
24 | REM ------------------------------------------------------------------------
25 | REM EXAMPLE:
26 | REM Table Fragmentation Characteristics
27 | REM
28 | REM Owner Table Name Exts Omega1 Chains
29 | REM -------- ---------------------------------------- ---- ------ -------
30 | REM scott s_emp 1 0.000 0
31 | REM ------------------------------------------------------------------------
32 | REM DISCLAIMER:
33 | REM This script is provided for educational purposes only. It is NOT
34 | REM supported by Oracle World Wide Technical Support.
35 | REM The script has been tested and appears to work as intended.
36 | REM You should always run new scripts on a test instance initially.
37 | REM ------------------------------------------------------------------------
38 | REM Main text of script follows:
39 |
40 | col towner heading 'Owner' format a8 trunc
41 | col tname heading 'Table Name' format a40 trunc
42 | col exts heading 'Exts' format 999 trunc
43 | col omega1 heading 'Omega1' format 0.999 trunc
44 | col chains heading 'Chains' format 99,990 trunc
45 |
46 | ttitle -
47 | center 'Table Fragmentation Characteristics' skip 2
48 |
49 | select owner towner,
50 | name tname,
51 | no_extents exts,
52 | (hwm - blks_w_rows)/(hwm + 0.0001) omega1,
53 | no_frag_rows chains
54 | from tfrag
55 | order by 1,2
56 | /
57 |
58 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/_Gentab.sql:
--------------------------------------------------------------------------------
1 | REM ***********************************************************
2 | REM This PL/SQL script Generates a Table creation script from
3 | REM the Data Dictionary. This script takes two parameters:
4 | REM owner and table name.
5 | REM The script can be customized to read the owner name and
6 | REM table name from a file and generate the table creation script.
7 | REM Privileged Users : SYSTEM, SYS or user having SELECT ANY TABLE
8 | REM system privilege
9 | REM
10 | REM Command Syntax:
11 | REM In SQL:
12 | REM SQL >@gentab.sql owner table_name
13 | REM Unix Shell:
14 | REM sqlplus system/manager << !
15 | REM @gentab.sql owner table_name
16 | REM !
17 | REM ***********************************************************
18 | set serveroutput on size 200000
19 | set echo off
20 | set feedback off
21 | set verify off
22 | set showmode off
23 | declare
24 | cursor TabCur is
25 | select table_name,owner,tablespace_name,initial_extent,next_extent,
26 | pct_used,pct_free,pct_increase,degree
27 | from sys.dba_tables
28 | where owner=upper('&&1') and
29 | table_name=upper('&&2');
30 | cursor ColCur(TableName varchar2) is
31 | select
32 | column_name col1,
33 | decode ( data_type,
34 | 'LONG', 'LONG ',
35 | 'LONG RAW', 'LONG RAW ',
36 | 'RAW', 'RAW ',
37 | 'DATE', 'DATE ',
38 | 'CHAR', 'CHAR' || '(' || DATA_LENGTH || ') ',
39 | 'VARCHAR2', 'VARCHAR2' || '(' || DATA_LENGTH || ') ',
40 | 'NUMBER', 'NUMBER' ||
41 | decode ( NVL ( DATA_PRECISION,0),
42 | 0, ' ',
43 | ' (' || DATA_PRECISION ||
44 | decode ( NVL ( DATA_SCALE, 0),
45 | 0, ') ',
46 | ',' || DATA_SCALE || ') '
47 | )
48 | )
49 | ) ||
50 | decode ( NULLABLE,
51 | 'N', 'NOT NULL',
52 | ' '
53 | ) col2
54 | from
55 | sys.dba_tab_columns
56 | where
57 | table_name=TableName and
58 | owner=upper('&&1')
59 | order by column_id;
60 | ColCount number(5);
61 | MaxCol number(5);
62 | FillSpace number(5);
63 | ColLen number(5);
64 | begin
65 | MaxCol:=0;
66 | for TabRec in TabCur loop
67 | select max(column_id) into MaxCol from sys.dba_tab_columns
68 | where table_name=TabRec.table_name and
69 | owner=TabRec.owner;
70 | dbms_output.put_line('CREATE TABLE '||TabRec.table_name);
71 | dbms_output.put_line('( ');
72 | ColCount:=0;
73 | for ColRec in ColCur(TabRec.table_name) loop
74 | ColLen:=length(ColRec.col1);
75 | FillSpace:=40 - ColLen;
76 | dbms_output.put(ColRec.col1);
77 | for i in 1..FillSpace loop
78 | dbms_output.put(' ');
79 | end loop;
80 | dbms_output.put(ColRec.col2);
81 | ColCount:=ColCount+1;
82 |
83 | if (ColCount < MaxCol) then
84 | dbms_output.put_line(',');
85 | else
86 | dbms_output.put_line(')');
87 | end if;
88 | end loop;
89 | dbms_output.put_line('TABLESPACE '||TabRec.tablespace_name);
90 | dbms_output.put_line('PCTFREE '||TabRec.pct_free);
91 | dbms_output.put_line('PCTUSED '||TabRec.pct_used);
92 | dbms_output.put_line('STORAGE ( ');
93 | dbms_output.put_line(' INITIAL '||TabRec.initial_extent);
94 | dbms_output.put_line(' NEXT '||TabRec.next_extent);
95 | dbms_output.put_line(' PCTINCREASE '||TabRec.pct_increase);
96 | dbms_output.put_line(' )');
97 | dbms_output.put_line('PARALLEL '||TabRec.degree);
98 | dbms_output.put_line('/');
99 | end loop;
100 | end;
101 | /
102 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/dbdesc.sql:
--------------------------------------------------------------------------------
1 | set heading on linesize 1500 pagesize 1000 termout on echo off feedback off verify off trims on
2 |
3 | col Username format a20 heading 'UTENTE'
4 | col BYTES_A format 999,999,999,999 HEADING 'SPAZIO|OCCUPATO'
5 | col TOT_TABLESPACE format 999,999,999,999 HEADING 'TOTALE|SPAZIO' noprint
6 | col TOTALE_TABLESPACE format 999,999,999,999 HEADING 'TOTALE|SPAZIO'
7 | col PCT format 99.99 HEADING 'PCT'
8 | col GRAPH format a30 HEADING 'GRAPH'
9 | col Created format a11 HEADING 'DATA|CREAZIONE'
10 |
11 | compute sum of BYTES_A on report
12 | break on report
13 |
14 | spool %WINDIR%\temp\VisSpace.txt
15 |
16 | select a.Username,
17 | to_char(c.Created,'DD-Mon-YYYY') Created,
18 | a.bytes BYTES_A,
19 | sum(b.bytes) TOT_TABLESPACE,
20 | (a.bytes/sum(b.bytes))*100 PCT,
21 | substr(d.descrizione,1,60) DESCRIZIONE,
22 | substr(d.rif,1,30) RIFERIMENTO
23 | from DBA_TS_QUOTAS a,
24 | dba_data_files b,
25 | all_users c,
26 | dbdesc d
27 | where a.tablespace_name = b.tablespace_name
28 | and a.Username = c.username
29 | and a.tablespace_name = 'USER_DATA'
30 | and a.username = d.utente (+)
31 | group by a.Username, to_char(c.Created,'DD-Mon-YYYY'), a.bytes, substr(d.descrizione,1,60), substr(d.rif,1,30)
32 | order by 5 desc
33 | /
34 |
35 | select sum(bytes) TOTALE_TABLESPACE
36 | from dba_data_files
37 | where tablespace_name = 'USER_DATA'
38 | /
39 | --clear compute
40 | --clear breaks
41 | spool off;
42 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/pkAutovalid.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE PACKAGE pkRecompilation AS
2 | PROCEDURE Compile_Object (aObjectName VARCHAR2, aForced BOOLEAN);
3 | PROCEDURE Compile_All (aForced BOOLEAN);
4 | END;
5 | /
6 | SHOW ERRORS;
7 |
8 | CREATE OR REPLACE PACKAGE BODY pkRecompilation AS
9 |
10 | FUNCTION GetObjectValidity (aObjectName VARCHAR2) RETURN BOOLEAN AS
11 |
12 | /*
13 | | Returns if an object is valid or not. for packages, the validity of BOTH
14 | specification and body
15 | | are tested: cValidity cursor will contain 2 rows, one for the
16 | specification, and one for the body
17 | */
18 |
19 | cursor cValidity (pObjectName VARCHAR2) IS
20 | SELECT STATUS FROM USER_OBJECTS WHERE UPPER(OBJECT_NAME) =
21 | UPPER(pObjectName);
22 | Result BOOLEAN;
23 |
24 | BEGIN
25 | Result := TRUE;
26 | FOR rValidity IN cValidity (aObjectName) LOOP
27 | Result := Result AND rValidity.STATUS = 'VALID';
28 | END LOOP;
29 | RETURN Result;
30 | END;
31 |
32 | /*****************************************************************************/
33 |
34 | FUNCTION GetObjectType (aObjectName VARCHAR2) RETURN VARCHAR2 AS
35 |
36 | /*
37 | | Returns the description for the type of the object : PROCEDURE, TABLE, ...
38 | | An error is raised if the object doesn't exist
39 | */
40 |
41 | cursor cObjectType (pObjectName VARCHAR2) IS
42 | SELECT OBJECT_TYPE FROM USER_OBJECTS WHERE
43 | UPPER(OBJECT_NAME) = UPPER(pObjectName);
44 | rObjectType cObjectType%ROWTYPE;
45 | BEGIN
46 |
47 | OPEN cObjectType (aObjectName);
48 |
49 | FETCH cObjectType INTO rObjectType;
50 |
51 | IF cObjectType%NOTFOUND THEN
52 | RAISE_APPLICATION_ERROR (-20001, 'Object Does not exist');
53 | ELSE
54 | RETURN rObjectType.OBJECT_TYPE;
55 | END IF;
56 |
57 | CLOSE cObjectType;
58 |
59 | EXCEPTION
60 | WHEN OTHERS THEN
61 | IF cObjectType%ISOPEN THEN
62 | CLOSE cObjectType;
63 | END IF;
64 | RAISE;
65 |
66 | END;
67 |
68 | /*****************************************************************************/
69 |
70 | PROCEDURE Compile_Object (aObjectName VARCHAR2, aForced BOOLEAN) AS
71 |
72 | /*
73 | | Compiles an object if it's invalid (or forced)
74 | | Compiles before the objects it's dependent on IN THE SAME SHEMA (objects
75 | of other owners won't be compiled)
76 | */
77 |
78 | CURSOR cDependencies (pObjectName VARCHAR2) IS
79 | SELECT OBJECT_NAME, STATUS FROM USER_OBJECTS WHERE
80 | OBJECT_NAME IN (select DISTINCT REFERENCED_NAME
81 | from user_dependencies WHERE UPPER(NAME) = UPPER(pObjectName))
82 | AND STATUS = 'INVALID';
83 | cRecompile INTEGER;
84 |
85 | BEGIN
86 |
87 | -- Compiles only if not valid
88 | IF (GetObjectValidity(aObjectName) = FALSE) OR (aForced = TRUE) THEN
89 | -- Compiles first objects aObjectName is dependent on
90 | FOR rDependency IN cDependencies (aObjectName) LOOP
91 | Compile_Object (rDependency.OBJECT_NAME, aForced);
92 | END LOOP;
93 |
94 | -- Then compiles object itself
95 | cRecompile := DBMS_SQL.OPEN_CURSOR;
96 | DBMS_SQL.PARSE (cRecompile, 'ALTER ' || GetObjectType(aObjectName) || ' ' || aObjectName || ' COMPILE',DBMS_SQL.NATIVE);
97 | DBMS_SQL.CLOSE_CURSOR (cRecompile);
98 |
99 | END IF;
100 |
101 | EXCEPTION
102 | WHEN OTHERS THEN
103 | IF cDependencies%ISOPEN THEN
104 | CLOSE cDependencies;
105 | END IF;
106 | RAISE;
107 | END;
108 |
109 | /*****************************************************************************/
110 |
111 | PROCEDURE Compile_All (aForced BOOLEAN) as
112 | cursor cObjectNames IS
113 | SELECT OBJECT_NAME FROM USER_OBJECTS
114 | WHERE STATUS = 'INVALID' AND
115 | (
116 | OBJECT_TYPE = 'FUNCTION' OR
117 | OBJECT_TYPE = 'PROCEDURE' OR
118 | OBJECT_TYPE = 'PACKAGE' OR
119 | OBJECT_TYPE = 'PACKAGE BODY'
120 | );
121 | BEGIN
122 | FOR rObjectName IN cObjectNames LOOP
123 | COMPILE_OBJECT (rObjectName.OBJECT_NAME, aForced);
124 | END LOOP;
125 |
126 | EXCEPTION
127 | WHEN OTHERS THEN
128 | IF cObjectNames%ISOPEN THEN
129 | CLOSE cObjectNames;
130 | END IF;
131 | RAISE;
132 | END;
133 |
134 | END;
135 | /
136 | SHOW ERRORS;
137 |
--------------------------------------------------------------------------------
/Script/To Verify/_Booo/show_fkchild.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenAllFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 | DA e VERSO la tabella passata come parametro.
11 |
12 | Parametri:
13 | 1. Nome Tabella
14 |
15 | */
16 |
17 | set serveroutput on verify off trims on feedback off
18 |
19 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
20 |
21 | declare
22 | cname varchar2(50);
23 | cname2 varchar2(50);
24 | r_user varchar2(50);
25 |
26 | cursor c1 is
27 | SELECT c.constraint_name,c.r_constraint_name cname2,
28 | c.table_name table1, r.table_name table2,
29 | decode(c.status,'DISABLED','DISABLE',' ') status,
30 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
31 | c.r_owner r_user
32 | from user_constraints c,
33 | user_constraints r
34 | where c.constraint_type='R' and
35 | c.r_constraint_name = r.constraint_name and
36 | r.table_name = upper('&nome_tabella');
37 |
38 | cursor c2 is
39 | select decode(position,1,'(',',')||column_name colname
40 | from user_cons_columns
41 | where constraint_name = cname
42 | order by position;
43 |
44 | cursor c3 is
45 | select decode(position,1,'(',',')||column_name refcol
46 | from all_cons_columns
47 | where constraint_name = cname2
48 | and owner = r_user
49 | order by position;
50 |
51 | begin
52 | dbms_output.enable(100000);
53 | for q1 in c1 loop
54 | cname := q1.constraint_name;
55 | cname2 := q1.cname2;
56 | r_user := q1.r_user;
57 |
58 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
59 | dbms_output.put('FOREIGN KEY ');
60 | for q2 in c2 loop
61 | dbms_output.put(q2.colname);
62 | end loop;
63 | dbms_output.put_line(')');
64 | dbms_output.put('REFERENCES '||q1.table2||' ');
65 | for q3 in c3 loop
66 | dbms_output.put(q3.refcol);
67 | end loop;
68 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
69 | dbms_output.put_line('/');
70 | end loop;
71 | end;
72 | /
73 | set serveroutput off verify on trims off feedback on;
74 |
75 |
--------------------------------------------------------------------------------
/Script/To Verify/_ReView.sql:
--------------------------------------------------------------------------------
1 |
2 | select column_name, column_id from user_tab_columns where table_name = 'LVXX_ARTICOLO';
3 |
4 | spool c:\temp\RevViews.sql
5 |
6 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
7 | set pages 0 lines 78 trims on
8 | column vtext format a78 wrap
9 | column AA NOPRINT
10 | column BB NOPRINT
11 | column CC NOPRINT
12 | select 'PROMPT *** Vista: '||upper(v.view_name)||chr(10)||chr(10)||'CREATE OR REPLACE VIEW '||upper(v.view_name)||CHR(10)||'('||column_name||') AS ',text,';' vtext,
13 | object_name AA,
14 | d.dlevel BB,
15 | o.object_type CC
16 | from sys.dba_objects o,
17 | sys.order_object_by_dependency d,
18 | all_views v,
19 | all_tab_columns ac
20 | where o.object_id = d.object_id(+)
21 | and o.object_type = 'VIEW'
22 | and o.owner = upper('CQ')
23 | and o.owner = v.owner
24 | and o.owner = ac.owner
25 | and v.view_name = o.object_name
26 | and v.view_name = ac.table_name
27 | order by d.dlevel desc, o.object_type
28 | /
29 |
30 | spool off
31 | set termout on feedback on verify on heading on
32 |
33 |
34 |
35 |
36 |
--------------------------------------------------------------------------------
/Script/To Verify/_RevView.sql:
--------------------------------------------------------------------------------
1 | spool c:\temp\RevViews.sql
2 |
3 | set heading off verify off feedback off arraysize 1 long 1000000 termout off
4 | set pages 0 lines 78 trims on
5 | column vtext format a78 wrap
6 | column AA NOPRINT
7 | column BB NOPRINT
8 | column CC NOPRINT
9 | select 'PROMPT *** Vista: '||upper(v.view_name)||chr(10)||chr(10)||'CREATE OR REPLACE VIEW '||upper(v.view_name)||' AS ',text,';' vtext,
10 | object_name AA,
11 | d.dlevel BB,
12 | o.object_type CC
13 | from sys.dba_objects o,
14 | sys.order_object_by_dependency d,
15 | all_views v
16 | where o.object_id = d.object_id(+)
17 | and o.object_type = 'VIEW'
18 | and o.owner = upper('CQ')
19 | and o.owner = v.owner
20 | and v.view_name = o.object_name
21 | order by d.dlevel desc, o.object_type
22 | /
23 |
24 | spool off
25 | set termout on feedback on verify on heading on
26 |
27 |
28 |
29 |
30 |
--------------------------------------------------------------------------------
/Script/To Verify/revPackage.sql:
--------------------------------------------------------------------------------
1 | COL SORT1 NOPRINT
2 | COL SORT2 NOPRINT
3 | COL SORT3 NOPRINT
4 | COL SORT4 NOPRINT
5 | BREAK ON SORT1 SKIP 1
6 | set linesize 120
7 | SET HEADING OFF
8 | SET ECHO OFF
9 | SET FEEDBACK OFF
10 | SET PAGESIZE 0
11 | SPOOL bldpack.sql
12 |
13 | select 'set echo on ' from dual;
14 | select 'spool bldpack.lst' from dual;
15 | select 'Remark Build package definitions' from dual;
16 |
17 | SELECT NAME SORT1, LINE SORT2,
18 | 'Create or Replace ' || TEXT
19 | FROM USER_SOURCE
20 | WHERE TYPE = 'PACKAGE'
21 | AND LINE = 1
22 | UNION
23 | SELECT NAME SORT1, LINE SORT2,
24 | TEXT
25 | FROM USER_SOURCE
26 | WHERE TYPE = 'PACKAGE'
27 | AND LINE > 1
28 | UNION
29 | SELECT NAME SORT1, 999999 SORT2,
30 | '/'
31 | FROM USER_SOURCE
32 | WHERE TYPE = 'PACKAGE'
33 | AND LINE = 1
34 | ORDER BY 1,2;
35 |
36 | spool off
37 | SPOOL bldpbdy.sql
38 |
39 | select 'set echo on ' from dual;
40 | select 'spool bldpbdy.lst' from dual;
41 | select 'Remark Build package body definitions' from dual;
42 |
43 | SELECT NAME SORT1, LINE SORT2,
44 | 'Create or Replace ' || TEXT
45 | FROM USER_SOURCE
46 | WHERE TYPE = 'PACKAGE BODY'
47 | AND LINE = 1
48 | UNION
49 | SELECT NAME SORT1, LINE SORT2,
50 | TEXT
51 | FROM USER_SOURCE
52 | WHERE TYPE = 'PACKAGE BODY'
53 | AND LINE > 1
54 | UNION
55 | SELECT NAME SORT1, 999999 SORT2,
56 | '/'
57 | FROM USER_SOURCE
58 | WHERE TYPE = 'PACKAGE BODY'
59 | AND LINE = 1
60 | ORDER BY 1,2;
61 | spool off
62 | SPOOL bldproc.sql
63 |
64 | select 'set echo on ' from dual;
65 | select 'spool bldproc.lst' from dual;
66 | select 'Remark Build procedure definitions' from dual;
67 |
68 | SELECT NAME SORT1, LINE SORT2,
69 | 'Create or Replace ' || TEXT
70 | FROM USER_SOURCE
71 | WHERE TYPE = 'PROCEDURE'
72 | AND LINE = 1
73 | UNION
74 | SELECT NAME SORT1, LINE SORT2,
75 | TEXT
76 | FROM USER_SOURCE
77 | WHERE TYPE = 'PROCEDURE'
78 | AND LINE > 1
79 | UNION
80 | SELECT NAME SORT1, 999999 SORT2,
81 | '/'
82 | FROM USER_SOURCE
83 | WHERE TYPE = 'PROCEDURE'
84 | AND LINE = 1
85 | ORDER BY 1,2;
86 |
87 | select 'Remark Build function definitions' from dual;
88 |
89 | SELECT NAME SORT1, LINE SORT2,
90 | 'Create or Replace ' || TEXT
91 | FROM USER_SOURCE
92 | WHERE TYPE = 'FUNCTION'
93 | AND LINE = 1
94 | UNION
95 | SELECT NAME SORT1, LINE SORT2,
96 | TEXT
97 | FROM USER_SOURCE
98 | WHERE TYPE = 'FUNCTION'
99 | AND LINE > 1
100 | UNION
101 | SELECT NAME SORT1, 999999 SORT2,
102 | '/'
103 | FROM USER_SOURCE
104 | WHERE TYPE = 'FUNCTION'
105 | AND LINE = 1
106 | ORDER BY 1,2;
107 |
108 | spool off
109 |
--------------------------------------------------------------------------------
/Script/To Verify/revPk.sql:
--------------------------------------------------------------------------------
1 | COL SORT1 NOPRINT
2 | COL SORT2 NOPRINT
3 | COL SORT3 NOPRINT
4 | COL SORT4 NOPRINT
5 | BREAK ON SORT2 SKIP 1
6 | set linesize 120
7 | SET HEADING OFF
8 | SET ECHO OFF
9 | SET FEEDBACK OFF
10 | SET PAGESIZE 0
11 | SPOOL bldpkcn.sql
12 |
13 | select 'set echo on ' from dual;
14 | select 'spool bldpkcn.lst' from dual;
15 | select 'Remark Build Primary Key constraints' from dual;
16 |
17 | SELECT TABLE_NAME SORT1, CONSTRAINT_NAME SORT2, 1 SORT3, 0 SORT4,
18 | 'ALTER TABLE '|| TABLE_NAME
19 | FROM USER_CONSTRAINTS
20 | WHERE CONSTRAINT_TYPE IN ('P','U')
21 | UNION
22 | SELECT TABLE_NAME SORT1, CONSTRAINT_NAME SORT2, 1 SORT3, 1 SORT4,
23 | ' ADD ( CONSTRAINT ' || CONSTRAINT_NAME ||
24 | decode (constraint_type,'P',' PRIMARY KEY (','U',' UNIQUE (',' NONE')
25 | FROM USER_CONSTRAINTS
26 | WHERE CONSTRAINT_TYPE IN ('P','U')
27 | UNION
28 | SELECT UC.TABLE_NAME SORT1, UC.CONSTRAINT_NAME SORT2, 2 SORT3,
29 | POSITION SORT4, ' '||COLUMN_NAME
30 | FROM USER_CONS_COLUMNS UCC, USER_CONSTRAINTS UC
31 | WHERE UCC.TABLE_NAME = UC.TABLE_NAME
32 | AND UCC.CONSTRAINT_NAME = UC.CONSTRAINT_NAME
33 | AND CONSTRAINT_TYPE IN ('P','U')
34 | AND POSITION = 1
35 | UNION
36 | SELECT UC.TABLE_NAME SORT1, UC.CONSTRAINT_NAME SORT2, 3 SORT3,
37 | POSITION SORT4, ' ,'||COLUMN_NAME
38 | FROM USER_CONS_COLUMNS UCC, USER_CONSTRAINTS UC
39 | WHERE UCC.TABLE_NAME = UC.TABLE_NAME
40 | AND UCC.CONSTRAINT_NAME = UC.CONSTRAINT_NAME
41 | AND UC.CONSTRAINT_TYPE IN ('P','U')
42 | AND POSITION <> 1
43 | UNION
44 | SELECT UI.TABLE_NAME SORT1, UC.CONSTRAINT_NAME SORT2, 5 SORT3, 0 SORT4,
45 | ' ) USING INDEX TABLESPACE ' || UI.TABLESPACE_NAME ||
46 | ' PCTFREE ' || UI.PCT_FREE
47 | FROM USER_INDEXES UI, USER_CONSTRAINTS UC
48 | WHERE UC.CONSTRAINT_TYPE IN ('P','U')
49 | AND UC.CONSTRAINT_NAME = UI.INDEX_NAME
50 | UNION
51 | SELECT UI.TABLE_NAME SORT1, UC.CONSTRAINT_NAME SORT2, 6 SORT3, 0 SORT4,
52 | ' STORAGE ( INITIAL ' || UI.INITIAL_EXTENT || ' NEXT ' ||
53 | UI.NEXT_EXTENT || ' PCTINCREASE ' || UI.PCT_INCREASE || ' ));'
54 | FROM USER_INDEXES UI, USER_CONSTRAINTS UC
55 | WHERE UC.CONSTRAINT_TYPE IN ('P','U')
56 | AND UC.CONSTRAINT_NAME = UI.INDEX_NAME
57 | ORDER BY 1, 2, 3, 4;
58 |
--------------------------------------------------------------------------------
/Script/To Verify/revView.sql:
--------------------------------------------------------------------------------
1 | SET HEADING OFF
2 | SET ECHO OFF
3 | SET FEEDBACK OFF
4 | SET PAGESIZE 0
5 | set numwidth 10
6 | SELECT uv.view_name SORT1, 0 SORT2, 0 SORT3, 0 SORT4,
7 | 'create or replace view '||uv.view_name ||' ('
8 | from dba_views uv
9 | WHERE uv.owner = upper('&2')
10 | and uv.view_name = upper('&1')
11 | union all
12 | SELECT utc.view_name SORT1, utc.column_id SORT2, 0 SORT3, 0 SORT4,
13 | utc.column_name
14 | from dba_tab_columns
15 | WHERE utc.owner = upper('&2')
16 | and utc.table_name = upper('&1')
17 | and utc.column_id = 1
18 | union all
19 | SELECT utc.view_name SORT1, utc.column_id SORT2, 0 SORT3, 0 SORT4,
20 | ' , '||utc.column_name
21 | from dba_tab_columns
22 | WHERE utc.owner = upper('&2')
23 | and utc.table_name = upper('&1')
24 | and utc.column_id <> 1
25 | SELECT uv.view_name SORT1, 999 SORT2, 0 SORT3, 0 SORT4,
26 | ' )'
27 | from dba_views uv
28 | WHERE uv.owner = upper('&2')
29 | and uv.view_name = upper('&1')
30 | ORDER BY 1, 2, 3, 4;
31 | SELECT uv.text
32 | from dba_views uv
33 | WHERE uv.owner = upper('&2')
34 | and uv.view_name = upper('&1')
35 | ;
36 | SELECT uv.view_name SORT1, 999 SORT2, 0 SORT3, 0 SORT4,
37 | ' ;'
38 | from dba_views uv
39 | WHERE uv.owner = upper('&2')
40 | and uv.view_name = upper('&1')
41 | ;
--------------------------------------------------------------------------------
/Script/trucchi.sql:
--------------------------------------------------------------------------------
1 | #per attivare trucco 1 (indifferentemente dalle statistiche)
2 | alter system set "_unnest_subquery" = false scope = SPFILE sid='ORCL';
3 | alter system set optimyzer = CHOOSE scope = SPFILE sid='ORCL';
4 |
5 | #trucco 2
6 | optimizer_index_cost_adj=100 (ridurlo a 50)
7 |
8 |
9 |
10 | # Nella 10 ritorna i param nascosti
11 | SELECT x.ksppinm NAME,
12 | y.ksppstvl VALUE,
13 | ksppdesc DESCRIPTION
14 | FROM x$ksppi x, sys.x$ksppcv y
15 | WHERE x.inst_id = userenv('Instance')
16 | AND y.inst_id = userenv('Instance')
17 | AND x.indx = y.indx
18 | AND SUBSTR(x.ksppinm,1,1) = '_'
19 | ORDER BY 1;
20 |
21 |
22 | #trigger che scatta in fase di logon
23 | CREATE OR REPLACE TRIGGER SESS_TRACE
24 | AFTER LOGON ON DATABASE
25 | DECLARE
26 | curr_sid number;
27 | curr_terminal varchar2(16);
28 | curr_PROGRAM varchar2(64);
29 | curr_USER varchar2(30);
30 | BEGIN
31 | select distinct a.sid, a.terminal, a.program , a.username
32 | into curr_sid, curr_terminal, curr_program , curr_user
33 | from v$session a
34 | where a.audsid = (select sys_context ('USERENV','SESSIONID') from dual);
35 | if (curr_USER = 'MARZO' or curr_USER = 'CLKANA') then
36 | execute immediate 'alter session set sql_trace=TRUE';
37 | end if;
38 | EXCEPTION
39 | WHEN OTHERS THEN
40 | NULL;
41 | END;
42 | /
43 |
44 |
45 | How can I find what the values are for the hidden (underscore) parameters ?
46 |
47 | --------------------------------------------------------------------------------
48 |
49 | Author's name: Connor McDonald
50 | Author's Email: connor_mcdonald@yahoo.com
51 | Date written: July 18, 2001
52 | Oracle version(s): 8.0+
53 |
54 | How can I find what the values are for the hidden (underscore) parameters ?
55 |
56 | Back to index of questions
57 |
58 |
59 | --------------------------------------------------------------------------------
60 |
61 | In trying to hunt down hidden parameters, we start by looking at the V$PARAMETER table to see where it sources its information from
62 |
63 | SQL> select VIEW_DEFINITION
64 | 2 from v$fixed_view_definition
65 | 3 where view_name = 'V$PARAMETER';
66 |
67 | select NUM , NAME , TYPE , VALUE , ISDEFAULT , ISSES_MODIFIABLE ,
68 | ISSYS_MODIFIABLE , ISMODIFIED , ISADJUSTED , DESCRIPTION
69 | from GV$PARAMETER where inst_id = USERENV('Instance')
70 |
71 | So lets try that again - this time GV$PARAMETER (the consolidated view of parameters across all instances)
72 |
73 | SQL> select VIEW_DEFINITION
74 | 2 from v$fixed_view_definition
75 | 3 where view_name = 'GV$PARAMETER';
76 |
77 | select x.inst_id,x.indx+1,ksppinm,ksppity,ksppstvl,ksppstdf,
78 | decode(bitand(ksppiflg/256,1),1,'TRUE','FALSE'),
79 | decode(bitand(ksppiflg/65536,3),1,'IMMEDIATE',2,'DEFERRED',3,'IMMEDIATE','FALSE'),
80 | decode(bitand(ksppstvf,7),1,'MODIFIED',4,'SYSTEM_MOD','FALSE'),
81 | decode(bitand(ksppstvf,2),2,'TRUE','FALSE'),
82 | ksppdesc
83 | from x$ksppi x,
84 | x$ksppcv y
85 | where (x.indx = y.indx)
86 | and (translate(ksppinm,'_','#') not like '#%'
87 | or (translate(ksppinm,'_','#') like '#%'and ksppstdf = 'FALSE'))
88 |
89 | From this output, its relatively straight forward to generate a query to list the hidden parameters and their descriptions
90 |
91 | select KSPPINM name,
92 | KSPPDESC description
93 | from X$KSPPI
94 | where substr(KSPPINM,1,1) = '_'
95 |
96 | which of course will only work as SYS. I have not included the values because whilst the hidden parameters have an associated entry in X$KSPPCV, this "value" is often ZERO, which is not necessarily the value actually in use by the instance, so interpreting them should take this into consideration. Similarly in OPS environments, you can restrict this for a particular instance in the same way that V$PARAMETER does
97 |
98 |
99 | SELECT KSPFTCTXPN, KSPPINM, KSPPITY, KSPFTCTXVL,
100 | KSPFTCTXDF, KSPPIFLG, KSPFTCTXVF
101 | FROM X$KSPPI X, X$KSPPCV2 Y
102 | WHERE (X.INDX+1) = KSPFTCTXPN
103 | and KSPPINM like '_unnest%' ;
--------------------------------------------------------------------------------
/TGenAllFK.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenAllFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 | DA e VERSO la tabella passata come parametro.
11 |
12 | Parametri:
13 | 1. Nome Tabella
14 |
15 | */
16 |
17 | set serveroutput on verify off trims on feedback off
18 |
19 | ACCEPT nome_tabella CHAR PROMPT 'Nome Tabella: '
20 |
21 | declare
22 | cname varchar2(50);
23 | cname2 varchar2(50);
24 | r_user varchar2(50);
25 |
26 | cursor c1 is
27 | select c.constraint_name,
28 | c.r_constraint_name cname2,
29 | c.table_name table1,
30 | r.table_name table2,
31 | decode(c.status,'DISABLED','DISABLE',' ') status,
32 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
33 | c.r_owner r_user
34 | from all_constraints c,
35 | all_constraints r
36 | where c.constraint_type='R'
37 | and c.r_constraint_name = r.constraint_name
38 | and c.table_name = upper('&nome_tabella')
39 | and c.owner = user
40 | and c.r_owner = r.owner
41 | union
42 | select c.constraint_name,c.r_constraint_name cname2,
43 | c.table_name table1, r.table_name table2,
44 | decode(c.status,'DISABLED','DISABLE',' ') status,
45 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
46 | c.r_owner r_user
47 | from user_constraints c,
48 | user_constraints r
49 | where c.constraint_type='R' and
50 | c.r_constraint_name = r.constraint_name and
51 | r.table_name = upper('&nome_tabella');
52 |
53 | cursor c2 is
54 | select decode(position,1,'(',',')||column_name colname
55 | from user_cons_columns
56 | where constraint_name = cname
57 | order by position;
58 |
59 | cursor c3 is
60 | select decode(position,1,'(',',')||column_name refcol
61 | from all_cons_columns
62 | where constraint_name = cname2
63 | and owner = r_user
64 | order by position;
65 |
66 | begin
67 | dbms_output.enable(100000);
68 | for q1 in c1 loop
69 | cname := q1.constraint_name;
70 | cname2 := q1.cname2;
71 | r_user := q1.r_user;
72 |
73 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
74 | dbms_output.put('FOREIGN KEY ');
75 | for q2 in c2 loop
76 | dbms_output.put(q2.colname);
77 | end loop;
78 | dbms_output.put_line(')');
79 | dbms_output.put('REFERENCES '||q1.table2||' ');
80 | for q3 in c3 loop
81 | dbms_output.put(q3.refcol);
82 | end loop;
83 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
84 | dbms_output.put_line('/');
85 | end loop;
86 | end;
87 | /
88 | set serveroutput off verify on trims off feedback on;
89 |
90 |
--------------------------------------------------------------------------------
/TGenFk.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenFK.sql
4 | ----------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni
10 | di una Tabella passata come parametro.
11 |
12 | Parametri:
13 | 1. Nome Tabella
14 |
15 | */
16 |
17 |
18 | set serveroutput on verify off trims on feedback off linesize 255;
19 |
20 | ACCEPT nome_tabella CHAR PROMPT 'Tabella: '
21 |
22 | PROMPT PROMPT *** Tabella: &nome_tabella
23 | PROMPT PROMPT ---------------------------------
24 |
25 | declare
26 | cname varchar2(50);
27 | cname2 varchar2(50);
28 | r_user varchar2(50);
29 | cursor c1 is
30 | select c.constraint_name,
31 | c.r_constraint_name cname2,
32 | c.table_name table1,
33 | r.table_name table2,
34 | decode(c.status,'DISABLED','DISABLE',' ') status,
35 | decode(c.delete_rule,'CASCADE',' ON DELETE CASCADE ',' ') delete_rule,
36 | c.r_owner r_user
37 | from all_constraints c,
38 | all_constraints r
39 | where c.constraint_type='R'
40 | and c.r_constraint_name = r.constraint_name
41 | and c.table_name = upper('&nome_tabella')
42 | and c.owner = user
43 | and c.r_owner = r.owner;
44 | cursor c2 is
45 | select decode(position,1,'(',',')||column_name colname
46 | from user_cons_columns
47 | where constraint_name = cname
48 | order by position;
49 | cursor c3 is
50 | select decode(position,1,'(',',')||column_name refcol
51 | from all_cons_columns
52 | where constraint_name = cname2
53 | and owner = r_user
54 | order by position;
55 | begin
56 | dbms_output.enable(999999);
57 | dbms_output.put_line(chr(0));
58 | for q1 in c1 loop
59 | cname := q1.constraint_name;
60 | cname2 := q1.cname2;
61 | r_user := q1.r_user;
62 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
63 | dbms_output.put('FOREIGN KEY ');
64 | for q2 in c2 loop
65 | dbms_output.put(q2.colname);
66 | end loop;
67 | dbms_output.put_line(')');
68 | dbms_output.put('REFERENCES '||q1.table2||' ');
69 | for q3 in c3 loop
70 | dbms_output.put(q3.refcol);
71 | end loop;
72 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
73 | dbms_output.put_line('/');
74 | end loop;
75 | dbms_output.put_line(chr(0));
76 | end;
77 | /
78 | set serveroutput off verify on trims off feedback on linesize 100;
--------------------------------------------------------------------------------
/TGenSovFK.sql:
--------------------------------------------------------------------------------
1 | /*
2 |
3 | TGenSovFK.sql
4 | -------------
5 | Ultima revisione:
6 | r1.1 del 09/12/98
7 |
8 | Descrizione:
9 | Ricostruzione degli statements di creazione delle relazioni definite
10 | sulle tabelle di uno schema verso un'altro schema
11 |
12 | Parametri:
13 | Nessuno
14 |
15 | */
16 |
17 |
18 | set serveroutput on verify off trims on feedback off
19 |
20 | declare
21 | cname varchar2(50);
22 | cname2 varchar2(50);
23 | r_user varchar2(50);
24 |
25 | cursor c1 is
26 | select c.constraint_name,
27 | c.r_constraint_name cname2,
28 | c.table_name table1,
29 | r.table_name table2,
30 | decode(c.status,'DISABLED','DISABLE',' ') status,
31 | decode(c.delete_rule,'CASCADE',' on delete cascade ',' ') delete_rule,
32 | c.r_owner r_user
33 | from all_constraints c,
34 | all_constraints r
35 | where c.constraint_type='R'
36 | and c.r_constraint_name = r.constraint_name
37 | and c.owner = user
38 | and c.r_owner != user
39 | and c.r_owner = r.owner;
40 |
41 | cursor c2 is
42 | select decode(position,1,'(',',')||column_name colname
43 | from user_cons_columns
44 | where constraint_name = cname
45 | order by position;
46 |
47 | cursor c3 is
48 | select decode(position,1,'(',',')||column_name refcol
49 | from all_cons_columns
50 | where constraint_name = cname2
51 | and owner = r_user
52 | order by position;
53 |
54 | begin
55 | dbms_output.enable(100000);
56 | for q1 in c1 loop
57 | cname := q1.constraint_name;
58 | cname2 := q1.cname2;
59 | r_user := q1.r_user;
60 |
61 | dbms_output.put_line('ALTER TABLE '||q1.table1||' DROP CONSTRAINT '||cname||';');
62 |
63 | dbms_output.put_line('ALTER TABLE '||q1.table1||' ADD CONSTRAINT '||cname);
64 | dbms_output.put('FOREIGN KEY ');
65 | for q2 in c2 loop
66 | dbms_output.put(q2.colname);
67 | end loop;
68 | dbms_output.put_line(')');
69 | dbms_output.put('REFERENCES '||q1.table2||' ');
70 | for q3 in c3 loop
71 | dbms_output.put(q3.refcol);
72 | end loop;
73 | dbms_output.put_line(') '||q1.delete_rule||q1.status);
74 | dbms_output.put_line('/');
75 | end loop;
76 | end;
77 | /
78 | set serveroutput off verify on trims off feedback on
--------------------------------------------------------------------------------
/Trace.sql:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 | ALTER SESSION SET SQL_TRACE=TRUE;
5 | alter system set timed_statistics= true
6 |
7 |
8 | -- se vuoi tracciare le biund variables
9 | ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 4';
10 |
11 | -- oppure
12 |
13 | ALTER SYSTEM SET EVENTS '10046 trace name context forever, level 12';
14 |
15 |
16 | select sid, serial#, username from v$session where sid = 80
17 |
18 |
19 | exec sys.dbms_system.set_sql_trace_in_session ( 80, 20044, true);
20 |
21 |
22 | exec sys.dbms_system.set_sql_trace_in_session ( 93, 9006, false);
23 |
24 |
25 | -- stop trace
26 | ALTER SYSTEM SET EVENTS '10046 trace name context off';
27 |
28 |
29 | select * from v$parameter
30 |
31 |
32 | select * from v$session_event
--------------------------------------------------------------------------------
/ar_move_tablespace.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE procedure ar_move_tablespace (dest_tablespace varchar2)
2 | is
3 | db_target user_tables.table_name%type;
4 |
5 | cursor nobuonetabelle
6 | is
7 | select distinct table_name from user_tab_columns where data_type in ('LONG');
8 |
9 | cursor nobuoneindici
10 | is
11 | select distinct index_name from user_indexes where index_type in ('LOB');
12 |
13 | cursor stat
14 | is
15 | select 'alter table ' || table_name || ' move tablespace '|| dest_tablespace STATEMENT
16 | from
17 | user_tables
18 | where tablespace_name != dest_tablespace
19 | and table_name not in (select distinct table_name from user_tab_columns where data_type in ('LONG'));
20 |
21 | cursor rebindx
22 | is
23 | select 'alter index ' || index_name || ' rebuild tablespace '|| dest_tablespace STATEMENT
24 | from
25 | user_indexes
26 | where tablespace_name != dest_tablespace
27 | and index_name not in (select distinct index_name from user_indexes where index_type in ('LOB'));
28 |
29 | begin
30 |
31 | for cur_row in stat loop
32 | begin
33 | execute immediate cur_row.STATEMENT;
34 | null;
35 | exception when others then
36 | raise_application_error (-20101, sqlerrm || '*** Errore: Spostamento Tablespace : ' ||cur_row.STATEMENT);
37 | end;
38 | end loop;
39 |
40 | for cur_indx in rebindx loop
41 | begin
42 | execute immediate cur_indx.STATEMENT;
43 | --null;
44 | exception when others then
45 | raise_application_error (-20101, sqlerrm || '*** Errore: Spostamento Indice : ' ||cur_indx.STATEMENT);
46 | end;
47 | end loop;
48 |
49 | for nogoodtable in nobuonetabelle loop
50 | dbms_output.put_line ('Non riesco a spostare la tabella.:'|| nogoodtable.table_name );
51 | end loop;
52 |
53 |
54 | for nogoodindex in nobuoneindici loop
55 | dbms_output.put_line ('Non riesco a spostare l''indice.:'|| nogoodindex.index_name );
56 | end loop;
57 |
58 | end;
59 | /
60 |
61 |
62 |
--------------------------------------------------------------------------------
/backup.sql:
--------------------------------------------------------------------------------
1 | rem -----------------------------------------------------------------------
2 | rem Filename: backup.sql
3 | rem Purpose: Generate script to do a simple on-line database backup.
4 | rem Notes: Adjust the copy_cmnd and copy_dest variables and run from
5 | rem sqlplus. Uncomment last few lines to do the actual backup.
6 | rem Author: Frank Naude, Oracle FAQ
7 | rem -----------------------------------------------------------------------
8 |
9 | set serveroutput on
10 | set trimspool on
11 | set line 500
12 | set head off
13 | set feed off
14 |
15 | spool backup.cmd
16 |
17 | declare
18 | copy_cmnd constant varchar2(30) := 'cp'; -- Use "ocopy" for NT
19 | copy_dest constant varchar2(30) := '/backup/'; -- C:\BACKUP\ for NT
20 |
21 | dbname varchar2(30);
22 | logmode varchar2(30);
23 | begin
24 | select name, log_mode
25 | into dbname, logmode
26 | from sys.v_$database;
27 |
28 | if logmode <> 'ARCHIVELOG' then
29 | raise_application_error(-20000,
30 | 'ERROR: Database must be in ARCHIVELOG mode!!!');
31 | return;
32 | end if;
33 |
34 | dbms_output.put_line('spool backup.'||dbname||'.'||
35 | to_char(sysdate, 'ddMonyy')||'.log');
36 |
37 | -- Loop through tablespaces
38 | for c1 in (select tablespace_name ts
39 | from sys.dba_tablespaces)
40 | loop
41 | dbms_output.put_line('alter tablespace '||c1.ts||' begin backup;');
42 | -- Loop through tablespaces' data files
43 | for c2 in (select file_name fil
44 | from sys.dba_data_files
45 | where tablespace_name = c1.ts)
46 | loop
47 | dbms_output.put_line('!'||copy_cmnd||' '||c2.fil||' '||copy_dest);
48 | end loop;
49 |
50 | dbms_output.put_line('alter tablespace '||c1.ts||' end backup;');
51 | end loop;
52 |
53 | -- Backup controlfile and switch logfiles
54 | dbms_output.put_line('alter database backup controlfile to trace;');
55 | dbms_output.put_line('alter database backup controlfile to '||''''||
56 | copy_dest||'control.'||dbname||'.'||
57 | to_char(sysdate,'DDMonYYHH24MI')||''''||';');
58 | dbms_output.put_line('alter system switch logfile;');
59 | dbms_output.put_line('spool off');
60 | end;
61 | /
62 |
63 | spool off
64 |
65 | set head on
66 | set feed on
67 | set serveroutput off
68 |
69 | -- Unremark/uncomment the following line to run the backup script
70 | -- @backup.cmd
71 | -- exit
72 |
73 |
--------------------------------------------------------------------------------
/drop_all_objects.sql:
--------------------------------------------------------------------------------
1 | -- replace schema-name
2 |
3 | BEGIN
4 | FOR cur_rec IN (SELECT object_name, object_type
5 | FROM all_objects
6 | WHERE object_type IN ('TABLE', 'VIEW', 'PACKAGE', 'PROCEDURE', 'FUNCTION', 'SEQUENCE') AND
7 | owner = '')
8 | LOOP
9 | BEGIN
10 | IF cur_rec.object_type = 'TABLE' THEN
11 | EXECUTE IMMEDIATE 'DROP ' || cur_rec.object_type || ' "' || cur_rec.object_name || '" CASCADE CONSTRAINTS';
12 | ELSE
13 | EXECUTE IMMEDIATE 'DROP ' || cur_rec.object_type || ' "' || cur_rec.object_name || '"';
14 | END IF;
15 | EXCEPTION
16 | WHEN OTHERS THEN
17 | DBMS_OUTPUT.put_line('FAILED: DROP ' || cur_rec.object_type || ' "' || cur_rec.object_name || '"');
18 | END;
19 | END LOOP;
20 | END;
21 | /
22 |
--------------------------------------------------------------------------------
/drop_queue_tables.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Il comando seguente disabilita l'errore oracle ORA-24005 che non
3 | permette al package di sistema DBMS_AQADM di droppare un oggetto che si chiama come uno esistente
4 | su sys ma su owner diverso.
5 |
6 | Ciao
7 |
8 | */
9 |
10 | ALTER session set events '10851 trace name context forever, level 2';
11 |
12 | drop table cineca.DEF$_AQCALL;
--------------------------------------------------------------------------------
/find_in_schema.sql:
--------------------------------------------------------------------------------
1 | /*
2 | How to execute:
3 |
4 | set serveroutput on size 1000000 format wrapped
5 | select find_in_schema('RBPRODSTG') from dual;
6 |
7 | */
8 |
9 | create or replace function find_in_schema(val varchar2)
10 | return varchar2 is
11 | v_old_table user_tab_columns.table_name%type;
12 | v_where Varchar2(4000);
13 | v_first_col boolean := true;
14 | type rc is ref cursor;
15 | c rc;
16 | v_rowid varchar2(20);
17 |
18 | begin
19 | for r in (
20 | select
21 | t.*
22 | from
23 | user_tab_cols t, user_all_tables a
24 | where t.table_name = a.table_name
25 | and t.data_type like '%CHAR%'
26 | order by t.table_name) loop
27 |
28 | if v_old_table is null then
29 | v_old_table := r.table_name;
30 | end if;
31 |
32 | if v_old_table <> r.table_name then
33 | v_first_col := true;
34 |
35 | -- dbms_output.put_line('searching ' || v_old_table);
36 |
37 | open c for 'select rowid from "' || v_old_table || '" ' || v_where;
38 |
39 | fetch c into v_rowid;
40 | loop
41 | exit when c%notfound;
42 | dbms_output.put_line(' rowid: ' || v_rowid || ' in ' || v_old_table);
43 | fetch c into v_rowid;
44 | end loop;
45 |
46 | v_old_table := r.table_name;
47 | end if;
48 |
49 | if v_first_col then
50 | v_where := ' where ' || r.column_name || ' like ''%' || val || '%''';
51 | v_first_col := false;
52 | else
53 | v_where := v_where || ' or ' || r.column_name || ' like ''%' || val || '%''';
54 | end if;
55 |
56 | end loop;
57 | return 'Success';
58 | end;
59 | /
60 |
--------------------------------------------------------------------------------
/gen_acl_script.sql:
--------------------------------------------------------------------------------
1 | select
2 | 'BEGIN DBMS_NETWORK_ACL_ADMIN.CREATE_ACL
3 | (acl => '''||acl||''','||'principal => '''||PRINCIPAL||''','||'is_grant => ' ||
4 | IS_GRANT||','||'privilege => '''||PRIVILEGE||'''); commit; END;'
5 | from dba_NETWORK_ACL_PRIVILEGES
6 | where privilege='connect'
7 | union all
8 | select
9 | 'BEGIN DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE
10 | (acl => '''||acl||''','||'principal => '''||PRINCIPAL||''','||'is_grant => ' ||
11 | IS_GRANT||','||'privilege => '''||PRIVILEGE||'''); commit; END;'
12 | from dba_NETWORK_ACL_PRIVILEGES
13 | where privilege<>'connect'
14 | union all
15 | select
16 | 'BEGIN DBMS_NETWORK_ACL_ADMIN.ASSIGN_ACL (acl => '''||acl||''', '||
17 | 'host => '''||host||''', '||
18 | 'lower_port => '||lower_port||', '||
19 | 'upper_port => '||upper_port||'); commit; END;'
20 | from dba_NETWORK_ACLS
21 | /
22 |
--------------------------------------------------------------------------------
/html_2_text.sql:
--------------------------------------------------------------------------------
1 | -- select pkg_html.to_text(testo) from api_msg_messages
2 | -- where user_id = '1122530'
3 |
4 | CREATE OR REPLACE AND RESOLVE JAVA SOURCE NAMED HTML as import javax.swing.text.BadLocationException;
5 | import javax.swing.text.Document;
6 | import javax.swing.text.html.HTMLEditorKit;
7 | import java.io.*;
8 | import java.io.File;
9 |
10 | import java.security.AccessControlException;
11 | import java.sql.*;
12 | import oracle.sql.driver.*;
13 | import oracle.sql.*;
14 |
15 |
16 | public class HTML extends Object
17 | {
18 | private static CLOB outCLOB;
19 | private static String retVal;
20 | private static int i;
21 | private static String p_in;
22 |
23 | public static CLOB to_text(CLOB p_ins)
24 |
25 | throws IOException, BadLocationException, AccessControlException, SQLException {
26 | if (p_ins == null)
27 | {
28 | Connection conn = DriverManager.getConnection("jdbc:default:connection:");
29 | outCLOB = CLOB.createTemporary((oracle.jdbc.OracleConnectionWrapper) conn, true, CLOB.DURATION_SESSION);
30 | i = outCLOB.setString(1, "");
31 | return outCLOB;
32 | }
33 |
34 |
35 | p_in = clobToString(p_ins).trim();
36 | if (p_in != null) {
37 | HTMLEditorKit kit = new HTMLEditorKit();
38 | Document doc = kit.createDefaultDocument();
39 | doc.putProperty("IgnoreCharsetDirective", new Boolean(true));
40 | kit.read(new StringReader(p_in), doc, 0);
41 | retVal = doc.getText(0, doc.getLength());
42 | Connection conn = DriverManager.getConnection("jdbc:default:connection:");
43 | outCLOB = CLOB.createTemporary((oracle.jdbc.OracleConnectionWrapper) conn, true, CLOB.DURATION_SESSION);
44 | i = outCLOB.setString(1, retVal);
45 | return outCLOB;
46 | } else
47 | {
48 | Connection conn = DriverManager.getConnection("jdbc:default:connection:");
49 | outCLOB = CLOB.createTemporary((oracle.jdbc.OracleConnectionWrapper) conn, true, CLOB.DURATION_SESSION);
50 | i = outCLOB.setString(1, "");
51 | return outCLOB;
52 | }
53 | }
54 |
55 | static private String clobToString(java.sql.Clob data) {
56 | final StringBuilder sb = new StringBuilder();
57 | try {
58 | final Reader reader = data.getCharacterStream();
59 | final BufferedReader br = new BufferedReader(reader);
60 | int b;
61 | while (-1 != (b = br.read())) {
62 | sb.append((char) b);
63 | }
64 | br.close();
65 | } catch (SQLException e) {
66 | return e.toString();
67 | } catch (IOException e) {
68 | return e.toString();
69 | }
70 | return sb.toString();
71 | }
72 | }
73 |
74 | /
75 |
76 |
77 | CREATE OR REPLACE PACKAGE pkg_html
78 | IS
79 | FUNCTION to_text ( html_in IN CLOB )
80 | RETURN CLOB
81 | IS
82 | language java
83 | name 'HTML.to_text( oracle.sql.CLOB ) return oracle.sql.CLOB';
84 |
85 | END pkg_html;
86 | /
87 |
88 |
--------------------------------------------------------------------------------
/invalid_synonyms.sql:
--------------------------------------------------------------------------------
1 | -- synonym referencing object exists in db, but INVALID state
2 | select 'drop synonym ' || synonym_name ||';'
3 | from user_synonyms
4 | where (table_owner, table_name) not in ( SELECT owner, object_name from all_objects );
5 |
6 | -- synonym referencing object NOT exists in DB
7 | select *
8 | from all_objects
9 | where (owner, object_name) in
10 | (select table_owner, table_name from user_synonyms )
11 | and status = 'INVALID';
12 |
--------------------------------------------------------------------------------
/show_locks_rac.sql:
--------------------------------------------------------------------------------
1 | SELECT DISTINCT
2 | To_char(SYSDATE, 'DD-MON-YYYY HH24:MI:SS') || chr(13) || chr(10)
3 | || ' User '
4 | || S1.username
5 | || '@'
6 | || S1.machine
7 | || ' ( INST='
8 | || S1.inst_id
9 | || ' SID='
10 | || S1.sid
11 | || ' SERIAL='
12 | || S1.serial#
13 | || ' OSUSER='
14 | || s1.osuser
15 | || ' ) ' || chr(13) || chr(10)
16 | || 'with the statement: ' || chr(13) || chr(10)
17 | || ' ' || sqlt2.sql_text || chr(13) || chr(10)
18 | || 'is blocking the SQL statement for ' ||L1.ctime ||' seconds on ' || S2.username || '@' || S2.machine || ' ( INST='|| S2.inst_id || ' SID=' || S2.sid || ' OSUSER=' || s2.osuser || ' ) ' || chr(13) || chr(10)
19 | || 'blocked SQL -> ' || chr(13) || chr(10)
20 | || ' ' || sqlt1.sql_text || chr(13) || chr(10)
21 | || 'kill statement:' || chr(13) || chr(10)
22 | || 'alter system kill session ''' || S1.sid ||','|| S1.serial# || ',' || '@' || S1.inst_id ||''' immediate;' AS blocking_status
23 | FROM gv$lock L1,
24 | gv$session S1,
25 | gv$lock L2,
26 | gv$session S2,
27 | gv$sql sqlt1,
28 | gv$sql sqlt2
29 | WHERE S1.sid = L1.sid
30 | AND S2.sid = L2.sid
31 | AND S1.inst_id = L1.inst_id
32 | AND S2.inst_id = L2.inst_id
33 | AND L1.BLOCK > 0
34 | AND L2.request > 0
35 | AND sqlt1.sql_id = s2.sql_id
36 | AND sqlt2.sql_id = s1.prev_sql_id
37 | AND L1.id1 = L2.id1
38 | AND L1.id2 = L2.id2
39 | -- AND L1.ctime > 300;
40 |
--------------------------------------------------------------------------------
/tbd_space.sql:
--------------------------------------------------------------------------------
1 | SELECT DS.TABLESPACE_NAME, SEGMENT_NAME, ROUND(SUM(DS.BYTES) / (1024 * 1024)) AS MB
2 | FROM DBA_SEGMENTS DS
3 | WHERE DS.SEGMENT_NAME in ('ADDRESS', 'PPCEXTDATA', 'USERDEMO', 'USERREG', 'XPRESCRIPTION' ) and DS.OWNER = 'IN'
4 | GROUP BY DS.TABLESPACE_NAME,
5 | SEGMENT_NAME;
6 |
7 |
8 |
--------------------------------------------------------------------------------
/win_expdp_full.bat:
--------------------------------------------------------------------------------
1 | @echo off
2 | SET ORACLE_SID=STEP
3 | SET HNAME=ITMILPPIMDB01
4 | SET BASE_FOLDER="K:\dbexports"
5 | SET DUMPFILE_FOLDER="K:\dbexports"
6 | SET ARCHIVE_PROGRAM="C:\Program Files\7-Zip\7z.exe"
7 | SET DATAPUMP_DIR="dbbackup"
8 |
9 | setlocal enabledelayedexpansion
10 |
11 | rem Ottieni la data e l'ora correnti
12 | for /f "delims=" %%A in ('wmic OS Get localdatetime ^| find "."') do set datetime=%%A
13 |
14 | rem Estrai l'anno, il mese, il giorno, l'ora e il minuto dalla data corrente
15 | set year=!datetime:~0,4!
16 | set month=!datetime:~4,2!
17 | set day=!datetime:~6,2!
18 | set hour=!datetime:~8,2!
19 | set minute=!datetime:~10,2!
20 |
21 | rem Costruisci il nome del file di log con il timestamp
22 | set exportfilename=%year%-%month%-%day%_%hour%-%minute%_%ORACLE_SID%_FULLEXP.DMP
23 | set logfilename=%year%-%month%-%day%_%hour%-%minute%_%ORACLE_SID%_FULLEXP.LOG
24 |
25 | REM Script begin
26 | expdp '/ as sysdba' full=y directory=%DATAPUMP_DIR% dumpfile=%exportfilename% logfile=%logfilename% flashback_time=SYSTIMESTAMP
27 |
28 | endlocal
29 |
30 |
31 |
32 |
33 | @echo off
34 | setlocal enabledelayedexpansion
35 |
36 | rem Definisci la directory in cui desideri eliminare i file
37 | set "directory=%DUMPFILE_FOLDER%"
38 |
39 | rem Definisci il numero massimo di file da mantenere (in questo caso, 7)
40 | set "keep=7"
41 |
42 | rem Elabora tutti i file nella directory specificata e crea un elenco ordinato per data
43 | for /f "delims=" %%A in ('dir /b /a-d /o-d "%directory%\*"') do (
44 | set /a "count+=1"
45 | if !count! gtr %keep% (
46 | echo Eliminazione di "%%A"
47 | del /q "%directory%\%%A"
48 | )
49 | )
50 |
51 | endlocal
52 |
53 |
54 |
55 |
56 | EXIT 0
57 |
--------------------------------------------------------------------------------
/write_clob_to_file.sql:
--------------------------------------------------------------------------------
1 | CREATE OR REPLACE procedure write_clob_to_file ( p_tabella varchar2)
2 | as
3 | file1 utl_file.file_type;
4 | l_buffer VARCHAR2 (32767);
5 | l_amount PLS_INTEGER := 32767;
6 | l_pos PLS_INTEGER := 1;
7 | l_lg PLS_INTEGER;
8 | begin
9 |
10 | dbms_output.put_line('--- Inzio Drop');
11 |
12 |
13 |
14 | file1:= utl_file.fopen('EXT_SCRIPT','script_cattolica.sql','wb', max_linesize => l_amount);
15 |
16 |
17 | for cur_file in (select TESTO_CREA as TESTO_CREA
18 | from appoggio_script a
19 | where (tabella = p_tabella or p_tabella = 'all')
20 | --and rownum < 100
21 | order by tabella)
22 | loop
23 |
24 | l_lg := dbms_lob.getlength(cur_file.TESTO_CREA);
25 |
26 | WHILE l_pos <= l_lg LOOP
27 | DBMS_LOB.read (cur_file.TESTO_CREA, l_amount, l_pos, l_buffer);
28 |
29 | utl_file.put_raw( file1, utl_raw.cast_to_raw(l_buffer)) ;
30 |
31 |
32 | l_pos := l_pos + l_amount;
33 | END LOOP;
34 | l_pos:=1;
35 | utl_file.put_raw( file1, utl_raw.cast_to_raw(chr(13) || chr(10)));
36 | UTL_FILE.fflush(file1);
37 |
38 | end loop;
39 |
40 |
41 | utl_file.fclose(file1);
42 |
43 | dbms_output.put_line('--- Fine');
44 |
45 | end;
46 | /
47 |
--------------------------------------------------------------------------------