The following script will enable session trace for the user scott. [oracle@canada u01]$ cat trace_trigger.sqlset echo on spool trace_trigger.log DROP TRIGGER SYS.trace_trigger; CREATE OR REPLACE TRIGGER sys.trace_trigger After logon on database Begin if ( user='SCOTT') then execute immediate 'alter session set sql_trace=true'; execute immediate 'alter session set timed_statistics=true'; execute immediate 'alter session set tracefile_identifier="SCOTT"'; execute immediate 'alter session set max_dump_file_size=unlimited'; execute immediate 'alter session set events ''10046 trace name context forever, level 12'''; End if; End; / spool off;
[oracle@canada u01]$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.1.0 Production on Tue Oct 22 06:04:31 2013 Copyright (c) 1982, 2009, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> @trace_trigger.sql SQL> SQL> spool trace_trigger.log SQL> SQL> DROP TRIGGER SYS.trace_trigger; DROP TRIGGER SYS.trace_trigger * ERROR at line 1: ORA-04080: trigger 'trace_trigger' does not exist SQL> SQL> CREATE OR REPLACE TRIGGER sys.trace_trigger 2 After logon on database 3 Begin 4 if ( user='SCOTT') then 5 execute immediate 'alter session set sql_trace=true'; 6 execute immediate 'alter session set timed_statistics=true'; 7 execute immediate 'alter session set tracefile_identifier="SCOTT"'; 8 execute immediate 'alter session set max_dump_file_size=unlimited'; 9 execute immediate 'alter session set events ''10046 trace name context forever, level 12'''; 10 End if; 11 End; 12 / Trigger created. SQL> SQL> spool off; SQL> SQL> select status from dba_triggers where trigger_name like'%TRACE_TRIGGER%';STATUS -------- ENABLED
To disable the trigger. SQL> alter trigger trace_trigger disable;Trigger altered.
SQL> select status from dba_triggers where trigger_name like'%TRACE_TRIGGER%';STATUS -------- DISABLED
To enable the trigger. SQL> alter trigger trace_trigger enable;Trigger altered.
SQL> select status from dba_triggers where trigger_name like'%TRACE_TRIGGER%';STATUS -------- ENABLED
Search This Blog
Tuesday, October 22, 2013
Create a System Trigger to Enable SQL TRACE for a session..
Sunday, October 6, 2013
Rman Disaster Recovery Walkthrough.
On Source Make a backup location.mkdir -p /u01/backup
Maker sure database is in archive log mode. Configure control file backup parameters in Rman. RMAN> configure controlfile autobackup on;new RMAN configuration parameters: CONFIGURE CONTROLFILE AUTOBACKUP ON; new RMAN configuration parameters are successfully stored
RMAN> configure controlfile autobackup format for device type disk to '/u01/backup/cf%F';new RMAN configuration parameters: CONFIGURE CONTROLFILE AUTOBACKUP FORMAT FOR DEVICE TYPE DISK TO '/u01/backup/cf%F'; new RMAN configuration parameters are successfully stored
Take backup of database plus archivelog. [oracle@canada ~]$ rman target /Recovery Manager: Release 11.2.0.1.0 - Production on Sat Oct 5 19:13:05 2013 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. connected to target database: DELL (DBID=3764293269)
RMAN> run 2> { 3> allocate channel c1 device type disk format '/u01/backup/%U'; 4> allocate channel c2 device type disk format '/u01/backup/%U'; 5> allocate channel c3 device type disk format '/u01/backup/%U'; 6> allocate channel c4 device type disk format '/u01/backup/%U'; 7> backup database plus archivelog; 8> }using target database control file instead of recovery catalog allocated channel: c1 channel c1: SID=51 device type=DISK allocated channel: c2 channel c2: SID=28 device type=DISK allocated channel: c3 channel c3: SID=49 device type=DISK allocated channel: c4 channel c4: SID=34 device type=DISK Starting backup at 05-OCT-13 current log archived channel c1: starting archived log backup set channel c1: specifying archived log(s) in backup set input archived log thread=1 sequence=3 RECID=1 STAMP=828040174 channel c1: starting piece 1 at 05-OCT-13 channel c2: starting archived log backup set channel c2: specifying archived log(s) in backup set input archived log thread=1 sequence=4 RECID=2 STAMP=828040176 input archived log thread=1 sequence=5 RECID=3 STAMP=828040184 channel c2: starting piece 1 at 05-OCT-13 channel c3: starting archived log backup set channel c3: specifying archived log(s) in backup set input archived log thread=1 sequence=6 RECID=4 STAMP=828040185 input archived log thread=1 sequence=7 RECID=5 STAMP=828040187 channel c3: starting piece 1 at 05-OCT-13 channel c4: starting archived log backup set channel c4: specifying archived log(s) in backup set input archived log thread=1 sequence=8 RECID=6 STAMP=828040188 input archived log thread=1 sequence=9 RECID=7 STAMP=828040446 channel c4: starting piece 1 at 05-OCT-13 channel c1: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/01ollp7v_1_1 tag=TAG20131005T191406 comment=NONE channel c1: backup set complete, elapsed time: 00:00:00 channel c2: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/02ollp7v_1_1 tag=TAG20131005T191406 comment=NONE channel c2: backup set complete, elapsed time: 00:00:00 channel c3: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/03ollp7v_1_1 tag=TAG20131005T191406 comment=NONE channel c3: backup set complete, elapsed time: 00:00:00 channel c4: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/04ollp7v_1_1 tag=TAG20131005T191406 comment=NONE channel c4: backup set complete, elapsed time: 00:00:01 Finished backup at 05-OCT-13 Starting backup at 05-OCT-13 channel c1: starting full datafile backup set channel c1: specifying datafile(s) in backup set input datafile file number=00001 name=/u01/app/oracle/oradata/dell/system01.dbf channel c1: starting piece 1 at 05-OCT-13 channel c2: starting full datafile backup set channel c2: specifying datafile(s) in backup set input datafile file number=00002 name=/u01/app/oracle/oradata/dell/sysaux01.dbf input datafile file number=00004 name=/u01/app/oracle/oradata/dell/users01.dbf channel c2: starting piece 1 at 05-OCT-13 channel c3: starting full datafile backup set channel c3: specifying datafile(s) in backup set input datafile file number=00005 name=/u01/app/oracle/oradata/dell/example01.dbf input datafile file number=00003 name=/u01/app/oracle/oradata/dell/undotbs01.dbf channel c3: starting piece 1 at 05-OCT-13 channel c3: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/07ollp81_1_1 tag=TAG20131005T191408 comment=NONE channel c3: backup set complete, elapsed time: 00:00:37 channel c2: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/06ollp81_1_1 tag=TAG20131005T191408 comment=NONE channel c2: backup set complete, elapsed time: 00:01:18 channel c1: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/05ollp81_1_1 tag=TAG20131005T191408 comment=NONE channel c1: backup set complete, elapsed time: 00:01:50 Finished backup at 05-OCT-13 Starting backup at 05-OCT-13 current log archived channel c1: starting archived log backup set channel c1: specifying archived log(s) in backup set input archived log thread=1 sequence=10 RECID=8 STAMP=828040560 channel c1: starting piece 1 at 05-OCT-13 channel c1: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/08ollpbg_1_1 tag=TAG20131005T191600 comment=NONE channel c1: backup set complete, elapsed time: 00:00:01 Finished backup at 05-OCT-13 Starting Control File and SPFILE Autobackup at 05-OCT-13 piece handle=/u01/backup/cfc-3764293269-20131005-00 comment=NONE Finished Control File and SPFILE Autobackup at 05-OCT-13 released channel: c1 released channel: c2 released channel: c3 released channel: c4
Take backup of spfile. RMAN> backup spfile to destination '/u01/backup/';Starting backup at 05-OCT-13 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=49 device type=DISK channel ORA_DISK_1: starting full datafile backup set channel ORA_DISK_1: specifying datafile(s) in backup set including current SPFILE in backup set channel ORA_DISK_1: starting piece 1 at 05-OCT-13 channel ORA_DISK_1: finished piece 1 at 05-OCT-13 piece handle=/u01/backup/DELL/backupset/2013_10_05/o1_mf_nnsnf_TAG20131005T192028_950694xh_.bkp tag=TAG20131005T192028 comment=NONE channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01 Finished backup at 05-OCT-13 Starting Control File and SPFILE Autobackup at 05-OCT-13 piece handle=/u01/backup/cfc-3764293269-20131005-01 comment=NONE Finished Control File and SPFILE Autobackup at 05-OCT-13
DBID of database to be restored DBID=3764293269 On new host where database is to be restored make required directories [oracle@newyork ~]$ mkdir -p /u01/app/oracle/admin/dell/adump [oracle@newyork ~]$ mkdir -p /u01/app/oracle/oradata/dell/ [oracle@newyork ~]$ mkdir -p /u01/app/oracle/flash_recovery_area/dell/ Copy backup files to the destination server. On Destination Server 1) Restore the spfile [oracle@newyork ~]$ export ORACLE_SID=dell [oracle@newyork ~]$ rman target / Recovery Manager: Release 11.2.0.1.0 - Production on Sat Oct 5 19:34:27 2013 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. connected to target database (not started) RMAN> set dbid=3764293269executing command: SET DBID
RMAN> startup force nomount;startup failed: ORA-01078: failure in processing system parameters LRM-00109: could not open parameter file '/u01/app/oracle/product/11.2.0/db_1/dbs/initdell.ora' starting Oracle instance without parameter file for retrieval of spfile Oracle instance started Total System Global Area 159019008 bytes Fixed Size 1335192 bytes Variable Size 75497576 bytes Database Buffers 79691776 bytes Redo Buffers 2494464 bytes
RMAN> restore spfile from '/u01/backup/cfc-3764293269-20131005-00';Starting restore at 05-OCT-13 using target database control file instead of recovery catalog allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=19 device type=DISK channel ORA_DISK_1: restoring spfile from AUTOBACKUP /u01/backup/cfc-3764293269-20131005-00 channel ORA_DISK_1: SPFILE restore from AUTOBACKUP complete Finished restore at 05-OCT-13
RMAN> shutdown immediateOracle instance shut down
2) Restore controlfile RMAN> startup nomountconnected to target database (not started) Oracle instance started Total System Global Area 272011264 bytes Fixed Size 1335952 bytes Variable Size 201330032 bytes Database Buffers 67108864 bytes Redo Buffers 2236416 bytes
RMAN> run 2> { 3> set controlfile autobackup format for device type disk to '/u01/backup/cf%F'; 4> restore controlfile from autobackup; 5> }executing command: SET CONTROLFILE AUTOBACKUP FORMAT Starting restore at 05-OCT-13 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=19 device type=DISK recovery area destination: /u01/app/oracle/flash_recovery_area database name (or database unique name) used for search: DELL channel ORA_DISK_1: no AUTOBACKUPS found in the recovery area channel ORA_DISK_1: looking for AUTOBACKUP on day: 20131005 channel ORA_DISK_1: AUTOBACKUP found: /u01/backup/cfc-3764293269-20131005-01 channel ORA_DISK_1: restoring control file from AUTOBACKUP /u01/backup/cfc-3764293269-20131005-01 channel ORA_DISK_1: control file restore from AUTOBACKUP complete output file name=/u01/app/oracle/oradata/dell/control01.ctl output file name=/u01/app/oracle/flash_recovery_area/dell/control02.ctl Finished restore at 05-OCT-13
3) Restore the database. RMAN> alter database mount;database mounted released channel: ORA_DISK_1
RMAN> catalog start with ' '; (if backup destination is different from source) RMAN> restore database;Starting restore at 05-OCT-13 Starting implicit crosscheck backup at 05-OCT-13 allocated channel: ORA_DISK_1 channel ORA_DISK_1: SID=19 device type=DISK Crosschecked 10 objects Finished implicit crosscheck backup at 05-OCT-13 Starting implicit crosscheck copy at 05-OCT-13 using channel ORA_DISK_1 Finished implicit crosscheck copy at 05-OCT-13 searching for all files in the recovery area cataloging files... no files cataloged using channel ORA_DISK_1 channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00003 to /u01/app/oracle/oradata/dell/undotbs01.dbf channel ORA_DISK_1: restoring datafile 00005 to /u01/app/oracle/oradata/dell/example01.dbf channel ORA_DISK_1: reading from backup piece /u01/backup/07ollp81_1_1 channel ORA_DISK_1: piece handle=/u01/backup/07ollp81_1_1 tag=TAG20131005T191408 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:23 channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00002 to /u01/app/oracle/oradata/dell/sysaux01.dbf channel ORA_DISK_1: restoring datafile 00004 to /u01/app/oracle/oradata/dell/users01.dbf channel ORA_DISK_1: reading from backup piece /u01/backup/06ollp81_1_1 channel ORA_DISK_1: piece handle=/u01/backup/06ollp81_1_1 tag=TAG20131005T191408 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:37 channel ORA_DISK_1: starting datafile backup set restore channel ORA_DISK_1: specifying datafile(s) to restore from backup set channel ORA_DISK_1: restoring datafile 00001 to /u01/app/oracle/oradata/dell/system01.dbf channel ORA_DISK_1: reading from backup piece /u01/backup/05ollp81_1_1 channel ORA_DISK_1: piece handle=/u01/backup/05ollp81_1_1 tag=TAG20131005T191408 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:58 Finished restore at 05-OCT-13
4) Recover the database RMAN> recover database;Starting recover at 05-OCT-13 using channel ORA_DISK_1 starting media recovery channel ORA_DISK_1: starting archived log restore to default destination channel ORA_DISK_1: restoring archived log archived log thread=1 sequence=10 channel ORA_DISK_1: reading from backup piece /u01/backup/08ollpbg_1_1 channel ORA_DISK_1: piece handle=/u01/backup/08ollpbg_1_1 tag=TAG20131005T191600 channel ORA_DISK_1: restored backup piece 1 channel ORA_DISK_1: restore complete, elapsed time: 00:00:01 archived log file name=/u01/app/oracle/flash_recovery_area/DELL/archivelog/2013_10_05/o1_mf_1_10_9507y3bg_.arc thread=1 sequence=10 channel default: deleting archived log(s) archived log file name=/u01/app/oracle/flash_recovery_area/DELL/archivelog/2013_10_05/o1_mf_1_10_9507y3bg_.arc RECID=9 STAMP=828042523 unable to find archived log archived log thread=1 sequence=11 RMAN-00571: =========================================================== RMAN-00569: =============== ERROR MESSAGE STACK FOLLOWS =============== RMAN-00571: =========================================================== RMAN-03002: failure of recover command at 10/05/2013 19:48:45 RMAN-06054: media recovery requesting unknown archived log for thread 1 with sequence 11 and starting SCN of 797450
Note: Ignore the error and relogin to thr rman prompt. 5) open with resetlogs [oracle@newyork ~]$ rman target / Recovery Manager: Release 11.2.0.1.0 - Production on Sat Oct 5 19:52:07 2013 Copyright (c) 1982, 2009, Oracle and/or its affiliates. All rights reserved. connected to target database: DELL (DBID=3764293269, not open) RMAN> sql 'alter database open resetlogs';using target database control file instead of recovery catalog sql statement: alter database open resetlogs
RMAN> exit Recovery Manager complete. 6) verify [oracle@newyork ~]$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.1.0 Production on Sat Oct 5 19:54:11 2013 Copyright (c) 1982, 2009, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> archive log list;Database log mode Archive Mode Automatic archival Enabled Archive destination USE_DB_RECOVERY_FILE_DEST Oldest online log sequence 1 Next log sequence to archive 1 Current log sequence 1
SQL> select name, dbid from v$database;NAME DBID --------- ---------- DELL 3764293269
Subscribe to:
Posts (Atom)