diff --git a/9781430248361.jpg b/9781430248361.jpg new file mode 100644 index 0000000..38cb6dd Binary files /dev/null and b/9781430248361.jpg differ diff --git a/LICENSE.txt b/LICENSE.txt new file mode 100644 index 0000000..bd7c470 --- /dev/null +++ b/LICENSE.txt @@ -0,0 +1,27 @@ +Freeware License, some rights reserved + +Copyright (c) 2013 Darl Kuhn, Sam Alapati, and Arup Nanda + +Permission is hereby granted, free of charge, to anyone obtaining a copy +of this software and associated documentation files (the "Software"), +to work with the Software within the limits of freeware distribution and fair use. +This includes the rights to use, copy, and modify the Software for personal use. +Users are also allowed and encouraged to submit corrections and modifications +to the Software for the benefit of other users. + +It is not allowed to reuse, modify, or redistribute the Software for +commercial use in any way, or for a user’s educational materials such as books +or blog articles without prior permission from the copyright holder. + +The above copyright notice and this permission notice need to be included +in all copies or substantial portions of the software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +AUTHORS OR COPYRIGHT HOLDERS OR APRESS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +SOFTWARE. + + diff --git a/README.md b/README.md new file mode 100644 index 0000000..03cba8a --- /dev/null +++ b/README.md @@ -0,0 +1,15 @@ +#Apress Source Code + +This repository accompanies [*RMAN Recipes for Oracle Database 12c*](http://www.apress.com/9781430248361) by Darl Kuhn, Sam Alapati, and Arup Nanda (Apress, 2013). + +![Cover image](9781430248361.jpg) + +Download the files as a zip using the green button, or clone the repository to your machine using Git. + +##Releases + +Release v1.0 corresponds to the code in the published book, without corrections or updates. + +##Contributions + +See the file Contributing.md for more information on how you can contribute to this repository. diff --git a/contributing.md b/contributing.md new file mode 100644 index 0000000..f6005ad --- /dev/null +++ b/contributing.md @@ -0,0 +1,14 @@ +# Contributing to Apress Source Code + +Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers. + +## How to Contribute + +1. Make sure you have a GitHub account. +2. Fork the repository for the relevant book. +3. Create a new branch on which to make your change, e.g. +`git checkout -b my_code_contribution` +4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted. +5. Submit a pull request. + +Thank you for your contribution! \ No newline at end of file diff --git a/scripts/listing02-3.sql b/scripts/listing02-3.sql new file mode 100644 index 0000000..18eec36 --- /dev/null +++ b/scripts/listing02-3.sql @@ -0,0 +1,5 @@ +SELECT + dest_name +,destination +FROM v$archive_dest +WHERE destination is not null; diff --git a/scripts/listing09-1.sh b/scripts/listing09-1.sh new file mode 100644 index 0000000..64efacc --- /dev/null +++ b/scripts/listing09-1.sh @@ -0,0 +1,99 @@ +# Beginning of Script +# Start of Configurable Section +export ORACLE_HOME=/opt/oracle/10.2/db_1 +export ORACLE_SID=PRODB1 +export TOOLHOME=/opt/oracle/tools +export BACKUP_MEDIA=DISK +export BACKUP_TYPE=FULL_DB_BKUP +export MAXPIECESIZE=16G +# End of Configurable Section +# Start of site specific parameters +export BACKUP_MOUNTPOINT=/oraback +export DBAEMAIL="dbas@proligence.com" +export DBAPAGER="dba.ops@proligence.com" +export LOG_SERVER=prolin2 +export LOG_USER=oracle +export LOG_DIR=/dbalogs +export CATALOG_CONN=${ORACLE_SID}/${ORACLE_SID}@catalog +# End of site specific parameters +export LOC_PREFIX=$BACKUP_MOUNTPOINT/loc +export TMPDIR=/tmp +export NLS_DATE_FORMAT="MM/DD/YY HH24:MI:SS" +export TIMESTAMP=`date +%T-%m-%d-%Y` +export LD_LIBRARY_PATH=$ORACLE_HOME/lib:/usr/lib:/lib +export LIBPATH=$ORACLE_HOME/lib:/usr/lib:/lib +export SHLIB_PATH=$ORACLE_HOME/lib:/usr/lib:/lib +export LOG=${TOOLHOME}/log +LOG=${LOG}/log/${ORACLE_SID}_${BACKUP_TYPE}_${BACKUP_MEDIA}_${TIMESTAMP}.log +export TMPLOG=$TOOLHOME/log/tmplog.$$ +echo `date` "Starting $BACKUP_TYPE Backup of $ORACLE_SID \ + to $BACKUP_MEDIA" > $LOG +export LOCKFILE=$TOOLHOME/${ORACLE_SID}_${BACKUP_TYPE}_${BACKUP_MEDIA}.lock +if [ -f $LOCKFILE ]; then + echo `date` "Script running. Exiting ..." >> $LOG + else + echo "Do NOT delete this file. Used for RMAN locking" > $LOCKFILE + $ORACLE_HOME/bin/rman log=$TMPLOG <> $LOG + rm $LOCKFILE + echo `date` "Script lock file removed" >> $LOG + if [ $RC -ne "0" ]; then + mailx -s "RMAN $BACKUP_TYPE $ORACLE_SID $BACKUP_MEDIA Failed" \ + $DBAEMAIL,$DBAPAGER < $LOG + else + cp $LOG ${LOC_PREFIX}1 + mailx -s "RMAN $BACKUP_TYPE $ORACLE_SID $BACKUP_MEDIA Successful" \ + $DBAEMAIL < $LOG + fi + scp $LOG ${LOG_USER}@${LOG_SERVER}:${LOG_DIR}/${ORACLE_SID}/. + rm $TMPLOG +fi diff --git a/scripts/listing09-10.rman b/scripts/listing09-10.rman new file mode 100644 index 0000000..5a1ed5b --- /dev/null +++ b/scripts/listing09-10.rman @@ -0,0 +1,10 @@ +create script full_disk_db +comment 'Full Backup as Backupset to Disk' +{ + allocate channel c1 type disk + format 'c:\backup\rman_%U.rman'; + backup + database + include current controlfile; + release channel c1; + } \ No newline at end of file diff --git a/scripts/listing09-2.txt b/scripts/listing09-2.txt new file mode 100644 index 0000000..df1e2ad --- /dev/null +++ b/scripts/listing09-2.txt @@ -0,0 +1,2 @@ +00 11 * * 0 /opt/oracle/tools/rman_full.disk.sh > /opt/oracle/tools/rman_full.disk.log 2>&1 +00 11 * * 0 /opt/oracle/tools/rman_arc.disk.sh > /opt/oracle/tools/rman_arc.disk.log 2>&1 diff --git a/scripts/listing09-3.bat b/scripts/listing09-3.bat new file mode 100644 index 0000000..a60484c --- /dev/null +++ b/scripts/listing09-3.bat @@ -0,0 +1,53 @@ +@ECHO OFF +:: Beginning of Script +:: Start of Configurable Section +set ORACLE_HOME=C:\oracle\product\12.1\db_1 +set ORACLE_SID=MOBDB10 +set TOOLHOME=C:\TOOLS +set BACKUP_MEDIA=DISK +set BACKUP_TYPE=FULL_DB_BKUP +set MAXPIECESIZE=16G +set BACKUP_MOUNTPOINT=c:\oracle\flash +set DBAEMAIL="dbas@proligence.com" +set DBAPAGER="dba.ops@proligence.com" +set CATALOG_CONN=%ORACLE_SID%/%ORACLE_SID%@catalog +set MS=mail.proligence.com +:: +:: end of Configurable Section +:: +set BACKUP_LOC_PREFIX=%BACKUP_MOUNTPOINT%\loc +set TMPDIR=C:\temp +set NLS_DATE_FORMAT="MM/DD/YY HH24:MI:SS" +realdate /d /s="set curdate=" > %TOOLHOME%\tmp_dt.bat +realdate /t /s="set curtime=" > %TOOLHOME%\tmp_tm.bat +call %TOOLHOME%\tmp_dt.bat +call %TOOLHOME%\tmp_tm.bat +:: +:: +set LOG=%TOOLHOME%\%ORACLE_SID%_%BACKUP_TYPE%_%BACKUP_MEDIA%_%CURDATE%_%CURTIME%.log +set TMPLOG=%TOOLHOME%\tmplog.$$ +:: +:: Build the Command File +set FORMATSTRING=%BACKUP_LOC_PREFIX%1\%ORACLE_SID%_%%u_%%p.rman +set CMDFILE=%TOOLHOME%\%ORACLE_SID%.rman +echo run { > %CMDFILE% +echo allocate channel c1 type disk >> %CMDFILE% +echo format '%FORMATSTRING%' >> %CMDFILE% +echo maxpiecesize %MAXPIECESIZE%; >> %CMDFILE% +echo backup >> %CMDFILE% +echo tablespace users; >> %CMDFILE% +echo release channel c1; >> %CMDFILE% +echo } >> %CMDFILE% +:: End of Command File Generation +:: +echo Starting the script > %LOG% +%ORACLE_HOME%\bin\rman target=/ catalog=%CATALOG_CONN% @%CMDFILE% log=%TMPLOG% +:: +:: Merge the Logfiles +type %TMPLOG% >> %LOG% +:: Check for errors +:: +echo THE OUTPUT WAS %ERRORLEVEL% >> %LOG% +findstr /i "error" %LOG% +if errorlevel 0 if not errorlevel 1 bmail -s %MS% -t %DBAPAGER% "Database" -m %LOG% +@echo on \ No newline at end of file diff --git a/scripts/listing09-7.rman b/scripts/listing09-7.rman new file mode 100644 index 0000000..88e5b66 --- /dev/null +++ b/scripts/listing09-7.rman @@ -0,0 +1,9 @@ +create script full_disk_db +{ + allocate channel c1 type disk + format '+DG1/%U.rmb'; + backup + database + include current controlfile; + release channel c1; +} \ No newline at end of file diff --git a/scripts/listing09-8.rman b/scripts/listing09-8.rman new file mode 100644 index 0000000..041fa92 --- /dev/null +++ b/scripts/listing09-8.rman @@ -0,0 +1,11 @@ +create global script gs_arc_disk_bkup +comment 'Global Script to Backup Arc Logs Delete Input' +{ + allocate channel c1 type disk + format 'C:\oraback\%U.rman'; + backup + archivelog + all + delete input; + release channel c1; +} \ No newline at end of file diff --git a/scripts/listing09-9.rman b/scripts/listing09-9.rman new file mode 100644 index 0000000..0ac699e --- /dev/null +++ b/scripts/listing09-9.rman @@ -0,0 +1,9 @@ +replace script full_disk_db +{ + allocate channel c1 type disk + format 'c:\backup\rman_%U.rman'; + backup + database + include current controlfile; + release channel c1; +} \ No newline at end of file diff --git a/scripts/listing10-3.sql b/scripts/listing10-3.sql new file mode 100644 index 0000000..23e179b --- /dev/null +++ b/scripts/listing10-3.sql @@ -0,0 +1,3 @@ +COL dbid NEW_VALUE hold_dbid +SELECT dbid FROM v$database; +exec dbms_system.ksdwrt(2,'DBID: '||TO_CHAR(&hold_dbid)); diff --git a/scripts/listing10-8.sql b/scripts/listing10-8.sql new file mode 100644 index 0000000..44413b6 --- /dev/null +++ b/scripts/listing10-8.sql @@ -0,0 +1,25 @@ +DECLARE + finished BOOLEAN; + v_dev_name VARCHAR2(75); +BEGIN + -- Allocate a channel, when disk then type = null + -- If tape then type = sbt_tape. + v_dev_name := dbms_backup_restore.deviceAllocate(type=>null, ident=>'d1'); + -- + dbms_backup_restore.restoreSetDatafile; + -- Destination and name for restored control file. + dbms_backup_restore.restoreControlFileTo(cfname=>'/tmp/control01.ctl'); + -- + -- Backup piece location and name. + dbms_backup_restore.restoreBackupPiece( + '/u01/rman/c-3412777350-20120722-00', finished); + -- + if finished then + dbms_output.put_line('Control file restored.'); + else + dbms_output.put_line('Problem'); + end if; + -- + dbms_backup_restore.deviceDeallocate('d1'); +END; +/ diff --git a/scripts/listing11-0.sql b/scripts/listing11-0.sql new file mode 100644 index 0000000..ba00424 --- /dev/null +++ b/scripts/listing11-0.sql @@ -0,0 +1,16 @@ +SELECT + a.thread#, b.open_mode, a.status, + CASE + WHEN ((b.open_mode='MOUNTED') AND (a.status='OPEN')) THEN + 'Crash Recovery req.' + WHEN ((b.open_mode='MOUNTED') AND (a.status='CLOSED')) THEN + 'No Crash Rec. req.' + WHEN ((b.open_mode='READ WRITE') AND (a.status='OPEN')) THEN + 'Inst. already open' + WHEN ((b.open_mode='READ ONLY') AND (a.status='CLOSED')) THEN + 'Inst. open read only' + ELSE 'huh?' + END STATUS +FROM v$thread a + ,gv$database b +WHERE a.thread# = b.inst_id; diff --git a/scripts/listing11-0b.sql b/scripts/listing11-0b.sql new file mode 100644 index 0000000..0c790ad --- /dev/null +++ b/scripts/listing11-0b.sql @@ -0,0 +1,24 @@ +SET LINES 132 +COL name FORM a40 +COL status FORM A8 +COL file# FORM 9999 +COL control_file_SCN FORM 999999999999999 +COL datafile_SCN FORM 999999999999999 +-- +SELECT +a.name +,a.status +,a.file# +,a.checkpoint_change# control_file_SCN +,b.checkpoint_change# datafile_SCN +,CASE +WHEN ((a.checkpoint_change# - b.checkpoint_change#) = 0) THEN 'Startup Normal' +WHEN ((b.checkpoint_change#) = 0) THEN 'File Missing?' +WHEN ((a.checkpoint_change# - b.checkpoint_change#) > 0) THEN 'Media Rec. Req.' +WHEN ((a.checkpoint_change# - b.checkpoint_change#) < 0) THEN 'Old Control File' +ELSE 'what the ?' +END datafile_status +FROM v$datafile a -- control file SCN for datafile + ,v$datafile_header b -- datafile header SCN +WHERE a.file# = b.file# +ORDER BY a.file#; diff --git a/scripts/listing11-1.sql b/scripts/listing11-1.sql new file mode 100644 index 0000000..50fb4a1 --- /dev/null +++ b/scripts/listing11-1.sql @@ -0,0 +1,2 @@ +select file#, status, error,recover from v$datafile_header; +select file#, online_status, error from v$recover_file; diff --git a/scripts/listing11-19.sql b/scripts/listing11-19.sql new file mode 100644 index 0000000..834a7e8 --- /dev/null +++ b/scripts/listing11-19.sql @@ -0,0 +1,30 @@ +SET SERVEROUTPUT ON +DECLARE + finished BOOLEAN; + v_dev_name VARCHAR2(10); + TYPE v_filestable IS TABLE OF varchar2(500) INDEX BY BINARY_INTEGER; +BEGIN + -- Allocate channel, when disk then type = null, if tape then type = sbt_tape. + v_dev_name := dbms_backup_restore.deviceAllocate(type=>null, ident=> 'd1'); + -- Set beginning of restore operation (does not restore anything yet). + dbms_backup_restore.restoreSetDatafile; + -- Define datafiles and locations for this backup piece. + dbms_backup_restore.restoreDatafileTo(dfnumber=>1, + toname=>'/u01/dbfile/o12c/system01.dbf'); + dbms_backup_restore.restoreDatafileTo(dfnumber=>4, + toname=>'/u01/dbfile/o12c/users01.dbf'); + dbms_backup_restore.restoreDatafileTo(dfnumber=>5, + toname=>'/u01/dbfile/o12c/tools01.dbf'); + -- Restore the datafiles in this backup piece. + dbms_backup_restore.restoreBackupPiece(done => finished, + handle=>'/u01/app/oracle/product/12.1.0.1/db_1/dbs/38nhakpe_1_1', + params=>null); + IF finished THEN + dbms_output.put_line('Datafiles restored'); + ELSE + dbms_output.put_line('Problem'); + END IF; + -- + dbms_backup_restore.deviceDeallocate('d1'); +END; +/ diff --git a/scripts/listing11-21a.sql b/scripts/listing11-21a.sql new file mode 100644 index 0000000..a3b0b51 --- /dev/null +++ b/scripts/listing11-21a.sql @@ -0,0 +1,17 @@ +set head off feed off verify off echo off pages 0 trimspool on +set lines 132 pagesize 0 +spo newname.sql +-- +select 'run{' from dual; +-- +select +'set newname for datafile ' || file# || ' to ' || '''' || name || '''' || ';' +from v$datafile; +-- +select +'restore database;' || chr(10) || +'switch datafile all;' || chr(10) || +'}' +from dual; +-- +spo off; diff --git a/scripts/listing11-21b.sql b/scripts/listing11-21b.sql new file mode 100644 index 0000000..101bcf0 --- /dev/null +++ b/scripts/listing11-21b.sql @@ -0,0 +1,8 @@ +select +file# +,status +,fuzzy +,error +,checkpoint_change#, +to_char(checkpoint_time,'dd-mon-rrrr hh24:mi:ss') as checkpoint_time +from v$datafile_header; diff --git a/scripts/listing11-21c.sql b/scripts/listing11-21c.sql new file mode 100644 index 0000000..2ccb8f1 --- /dev/null +++ b/scripts/listing11-21c.sql @@ -0,0 +1,8 @@ +set head off feed off verify off echo off pages 0 trimspool on +set lines 132 pagesize 0 +spo renlog.sql +select +'alter database rename file ' || chr(10) +|| '''' || member || '''' || ' to ' || chr(10) || '''' || member || '''' ||';' +from v$logfile; +spo off; diff --git a/scripts/listing12-0.sql b/scripts/listing12-0.sql new file mode 100644 index 0000000..7625930 --- /dev/null +++ b/scripts/listing12-0.sql @@ -0,0 +1,8 @@ +select + file# +,status +,fuzzy +,error +,checkpoint_change#, +to_char(checkpoint_time,'dd-mon-rrrr hh24:mi:ss') as checkpoint_time +from v$datafile_header; diff --git a/scripts/listing12-13.sql b/scripts/listing12-13.sql new file mode 100644 index 0000000..2aee0b0 --- /dev/null +++ b/scripts/listing12-13.sql @@ -0,0 +1,8 @@ +SELECT + file# +,fuzzy +,status +,checkpoint_change# +,to_char(checkpoint_time,'dd-mon-rrrr hh24:mi:ss') +,error +FROM v$datafile_header; diff --git a/scripts/listing12-3.sql b/scripts/listing12-3.sql new file mode 100644 index 0000000..aa3e370 --- /dev/null +++ b/scripts/listing12-3.sql @@ -0,0 +1,13 @@ +SELECT + sequence# +,first_change# +,first_time +FROM v$log_history +ORDER BY first_time; +-- +SELECT + sequence# +,first_change# +,first_time +FROM v$archived_log +ORDER BY first_time; diff --git a/scripts/listing12-6.sql b/scripts/listing12-6.sql new file mode 100644 index 0000000..2be49a9 --- /dev/null +++ b/scripts/listing12-6.sql @@ -0,0 +1,6 @@ +SELECT + sequence# +,first_change# +,first_time +FROM v$archived_log +ORDER BY first_time; diff --git a/scripts/listing12-7.sql b/scripts/listing12-7.sql new file mode 100644 index 0000000..b8747bf --- /dev/null +++ b/scripts/listing12-7.sql @@ -0,0 +1,2 @@ +SELECT name, scn, time, guarantee_flashback_database +FROM v$restore_point; diff --git a/scripts/listing13-17.sql b/scripts/listing13-17.sql new file mode 100644 index 0000000..01275fd --- /dev/null +++ b/scripts/listing13-17.sql @@ -0,0 +1,5 @@ +col type format a5 +col original_name format a15 +col object_name format a15 +select original_name, object_name, type, can_undrop +from user_recyclebin; \ No newline at end of file diff --git a/scripts/listing13-20.sql b/scripts/listing13-20.sql new file mode 100644 index 0000000..30fb832 --- /dev/null +++ b/scripts/listing13-20.sql @@ -0,0 +1,13 @@ +select + acc_status, + versions_starttime, + versions_startscn, + versions_endtime, + versions_endscn, + versions_xid, + versions_operation + from accounts + versions between scn minvalue and maxvalue + where accno = 3760 + order by 3 + / \ No newline at end of file diff --git a/scripts/listing13-22.rman b/scripts/listing13-22.rman new file mode 100644 index 0000000..45c793a --- /dev/null +++ b/scripts/listing13-22.rman @@ -0,0 +1,4 @@ +recover table SCOTT.ACCOUNTS +until scn 2012991 +auxiliary destination '+DG1' +; \ No newline at end of file diff --git a/scripts/listing13-24.rman b/scripts/listing13-24.rman new file mode 100644 index 0000000..d59fe26 --- /dev/null +++ b/scripts/listing13-24.rman @@ -0,0 +1,4 @@ +recover table arup.accounts +until scn 1799975 +auxiliary destination '+DG1' +remap table arup.accounts:accounts_new; \ No newline at end of file diff --git a/scripts/listing13-25.rman b/scripts/listing13-25.rman new file mode 100644 index 0000000..398c195 --- /dev/null +++ b/scripts/listing13-25.rman @@ -0,0 +1,4 @@ +recover table arup.accounts +until scn 1799975 +auxiliary destination '+DG1' +remap tablespace users:accdata; \ No newline at end of file diff --git a/scripts/listing13-26.rman b/scripts/listing13-26.rman new file mode 100644 index 0000000..7e03f00 --- /dev/null +++ b/scripts/listing13-26.rman @@ -0,0 +1,5 @@ +recover table scott.accounts +until scn 1792736 +auxiliary destination '+DG1' +datapump destination '/tmp' dump file 'accounts.dmp' +notableimport; \ No newline at end of file diff --git a/scripts/listing14-1.sql b/scripts/listing14-1.sql new file mode 100644 index 0000000..d932119 --- /dev/null +++ b/scripts/listing14-1.sql @@ -0,0 +1,11 @@ +SELECT + a.group# +,a.thread# +,a.status grp_status +,b.member member +,b.status mem_status +,a.bytes/1024/1024 mbytes +FROM v$log a, + v$logfile b +WHERE a.group# = b.group# +ORDER BY a.group#, b.member; diff --git a/scripts/listing14-2.bsh b/scripts/listing14-2.bsh new file mode 100644 index 0000000..d52c941 --- /dev/null +++ b/scripts/listing14-2.bsh @@ -0,0 +1,28 @@ +#!/bin/bash +export DBS="ENGDEV STAGE OTEST" +export MAILLIST="larry@support.com" +export BOX=`uname -a | awk '{print$2}'` +#----------------------------------------------------------- +for instance in $DBS +do +# call script to source oracle OS variables +. /etc/oraset $instance +crit_var=$( +sqlplus -s < totalwork; +-- +SELECT s.client_info, + sl.opname, + sl.message, + sl.sid, sl.serial#, p.spid, + sl.sofar, sl.totalwork, + round(sl.sofar/sl.totalwork*100,2) "% Complete" +FROM v$session_longops sl, v$session s, v$process p +WHERE p.addr = s.paddr +AND sl.sid=s.sid +AND sl.serial#=s.serial# +AND opname LIKE 'RMAN%' +AND opname NOT LIKE '%aggregate%' +AND totalwork != 0 +AND sofar <> totalwork; +-- +select sid, serial#, sofar, totalwork,opname, +round(sofar/totalwork*100,2) "% Complete" +from v$session_longops +where opname LIKE 'RMAN%aggregate%' +and totalwork != 0 +and sofar <> totalwork; +-- +SET LINES 200 +COL opname FORM A35 +COL pct_complete FORM 99.99 HEAD "% Comp." +COL start_time FORM A15 HEAD "Start|Time" +COL hours_running FORM 9999.99 HEAD "Hours|Running" +COL minutes_left FORM 999999 HEAD "Minutes|Left" +COL est_comp_time FORM A15 HEAD "Est. Comp.|Time" +-- +SELECT sid, serial#, opname, +ROUND(sofar/totalwork*100,2) AS pct_complete, +TO_CHAR(start_time,'dd-mon-yy hh24:mi') start_time, +(sysdate-start_time)*24 hours_running, +((sysdate-start_time)*24*60)/(sofar/totalwork)-(sysdate-start_time) + *24*60 minutes_left, +TO_CHAR((sysdate-start_time)/(sofar/totalwork)+start_time,'dd-mon-yy hh24:mi') + est_comp_time +FROM v$session_longops +WHERE opname LIKE 'RMAN%' +AND opname NOT LIKE '%aggregate%' +AND totalwork != 0 +AND sofar <> totalwork; diff --git a/scripts/listing16-3.sql b/scripts/listing16-3.sql new file mode 100644 index 0000000..aebdf63 --- /dev/null +++ b/scripts/listing16-3.sql @@ -0,0 +1,34 @@ +SET PAGESIZE 50 +COL time_taken_display FORM A10 HEAD "Time|Taken|HH:MM:SS" +COL rman_end_time FORM A17 +COL i_size_gig FORM 999.99 HEAD "Input|Gig" +COL o_size_gig FORM 999.99 HEAD "Output|Gig" +COL compression_ratio FORM 99.99 HEAD "Comp.|Ratio" +COL status FORM A12 +COL input_type FORM A14 +-- +SELECT + time_taken_display +,TO_CHAR(end_time,'dd-mon-rrrr hh24:mi') AS rman_end_time +,input_bytes/1024/1024/1024 i_size_gig +,output_bytes/1024/1024/1024 o_size_gig +,compression_ratio +,status +,input_type +FROM v$rman_backup_job_details +ORDER BY end_time; +-- +SELECT + ROUND((end_time - start_time)*24*60,2) AS minutes +,end_time +,RANK() OVER (ORDER BY end_time - start_time DESC) rank_row +,ROUND( + AVG((end_time - start_time)*24*60) OVER () + ,2) average_all +,ROUND( + AVG((end_time - start_time)*24*60) + OVER (ORDER BY rownum + ROWS BETWEEN 3 PRECEDING AND 1 PRECEDING) + ,2) average_prev_3 +FROM v$rman_backup_job_details +ORDER BY end_time; diff --git a/scripts/listing16-5.rman b/scripts/listing16-5.rman new file mode 100644 index 0000000..0750348 --- /dev/null +++ b/scripts/listing16-5.rman @@ -0,0 +1,22 @@ +rman msgno log=rman_debug01.log trace rman_debug01.trc << EOF +set echo on +connect target / +alter session set max_dump_file_size=UNLIMITED; +alter session set tracefile_identifier='rmanbackup_10046_trace_file'; +alter session set events '10046 trace name context forever, level 12'; +debug all; +backup database; +debug off; +EOF +-- +rman msgno log=rman_debug01.log trace rman_debug01.trc << EOF +set echo on +connect target / +sql "alter session set max_dump_file_size=UNLIMITED"; +sql "alter session set tracefile_identifier=''rmanbackup_10046_trace_file''"; +sql "alter session set events ''10046 trace name context forever, level 12''"; +debug all; +backup database; +debug off; +EOF + diff --git a/scripts/listing16-5.trg b/scripts/listing16-5.trg new file mode 100644 index 0000000..f5e8776 --- /dev/null +++ b/scripts/listing16-5.trg @@ -0,0 +1,11 @@ +create or replace trigger trace_rcat +after logon on database +declare + trace_string varchar2(100); +begin +if user='RCAT' then + dbms_monitor.session_trace_enable(null, null, true, true); + SELECT 'RMAN SQL TRACE FILE' INTO trace_string FROM dual; +end if; +end; +/ diff --git a/scripts/listing16-6.rman b/scripts/listing16-6.rman new file mode 100644 index 0000000..0867ec3 --- /dev/null +++ b/scripts/listing16-6.rman @@ -0,0 +1,7 @@ +rman msgno log=rman_debug01.log trace rman_debug01.trc << EOF +set echo on +connect target / +debug io; +backup database; +debug off; +EOF diff --git a/scripts/listing16-7.sql b/scripts/listing16-7.sql new file mode 100644 index 0000000..b0a984d --- /dev/null +++ b/scripts/listing16-7.sql @@ -0,0 +1,11 @@ +SELECT sid, serial, filename, type, elapsed_time, + effective_bytes_per_second +FROM v$backup_async_io +WHERE close_time > sysdate – 7; +-- +SELECT filename, sid, serial, close_time, long_waits/io_count as ratio +FROM v$backup_async_io +WHERE type != 'AGGREGATE' +AND SID = &SID +AND SERIAL = &SERIAL +ORDER BY ratio desc; diff --git a/scripts/listing17-16.sql b/scripts/listing17-16.sql new file mode 100644 index 0000000..772af1f --- /dev/null +++ b/scripts/listing17-16.sql @@ -0,0 +1,6 @@ +SELECT concat('+'||gname, sys_connect_by_path(aname, '/')) full_alias_path FROM +(SELECT g.name gname, a.parent_index pindex, a.name aname, +a.reference_index rindex FROM v$asm_alias a, v$asm_diskgroup g +WHERE a.group_number = g.group_number) +START WITH (mod(pindex, power(2, 24))) = 0 +CONNECT BY PRIOR rindex = pindex; diff --git a/scripts/listing17-17.bsh b/scripts/listing17-17.bsh new file mode 100644 index 0000000..add7887 --- /dev/null +++ b/scripts/listing17-17.bsh @@ -0,0 +1,24 @@ +#!/bin/bash +# +if [ $# -ne 2 ]; then + echo "Usage: $0 SID threshold" + exit 1 +fi +# source oracle OS variables +. /var/opt/oracle/oraset $1 +crit_var=$(sqlplus -s < $2; +EOF) +# +if [ $crit_var -ne 0 ]; then + echo "rman backups not running on $1" | mailx -s "rman problem" dbasupport@gmail.com +else + echo "rman backups ran ok" +fi +# +exit 0 diff --git a/scripts/listing17-17b.bsh b/scripts/listing17-17b.bsh new file mode 100644 index 0000000..b3efb78 --- /dev/null +++ b/scripts/listing17-17b.bsh @@ -0,0 +1,32 @@ +#!/bin/bash +# +if [ $# -ne 2 ]; then + echo "Usage: $0 SID threshold" + exit 1 +fi +# source oracle OS variables +. /var/opt/oracle/oraset $1 +crit_var2=$(sqlplus -s < sysdate - $2); +EOF) +# +if [ $crit_var2 -ne 0 ]; then + echo "datafile not backed up on $1" | mailx -s "backup problem" dbasupport@gmail.com +else + echo "datafiles are backed up..." +fi +# +exit 0 diff --git a/scripts/listing17-5.sql b/scripts/listing17-5.sql new file mode 100644 index 0000000..2c01511 --- /dev/null +++ b/scripts/listing17-5.sql @@ -0,0 +1,18 @@ +SELECT + a.username +,a.sid +,a.serial# +,b.spid AS OS_ID +,a.client_info +FROM v$session a + ,v$process b +WHERE a.program like '%rman%' +AND a.paddr = b.addr; +-- +SELECT sid, serial#, sofar, totalwork, opname, +round(sofar/totalwork*100,2) AS pct_complete +FROM v$session_longops +WHERE opname LIKE 'RMAN%' +AND opname NOT LIKE '%aggregate%' +AND totalwork != 0 +AND sofar <> totalwork; diff --git a/scripts/listing17-8.sql b/scripts/listing17-8.sql new file mode 100644 index 0000000..df49003 --- /dev/null +++ b/scripts/listing17-8.sql @@ -0,0 +1,31 @@ +select + sid +,recid +,output +from v$rman_output +order by recid; +-- +select + a.sid +,a.recid +,b.operation +,b.status +,a.output +from v$rman_output a + ,v$rman_status b +where a.rman_status_recid = b.recid +and a.rman_status_stamp = b.stamp +order by a.recid; +-- +select + a.sid +,a.recid +,b.operation +,b.status +,a.output +from v$rman_output a + ,v$rman_status b +where a.rman_status_recid = b.recid +and a.rman_status_stamp = b.stamp +and b.status = 'RUNNING' +order by a.recid; diff --git a/scripts/listing17-9.bsh b/scripts/listing17-9.bsh new file mode 100644 index 0000000..33b3c3d --- /dev/null +++ b/scripts/listing17-9.bsh @@ -0,0 +1,22 @@ +#!/bin/bash +export NLS_DATE_FORMAT="DD-MON-RRRR HH24:MI:SS" +export dateNOW=$(date +%Y%m%d%H%M%S) +rman msgno log=${ORACLE_SID}_${dateNOW}_rmanout.log \ + trace=${ORACLE_SID}_${dateNOW}_rmanout.trc << EOF +set echo on +connect target / +show all; +report schema; +host "sqlplus '/ as sysdba' @precmd.sql"; +host "mv precmd.lst ${ORACLE_SID}_${dateNOW}_precmd.lst"; +run { + sql "alter session set max_dump_file_size=UNLIMITED"; + sql "alter session set tracefile_identifier=''rmanbackup_10046_trace_file''"; + sql "alter session set events ''10046 trace name context forever, level 12''"; + debug all; + <<>> + debug off; +} +host "sqlplus '/ as sysdba' @postcmd.sql"; +host "mv postcmd.lst ${ORACLE_SID}_${dateNOW}_postcmd.lst"; +EOF diff --git a/scripts/listing17-9_postcmd.sql b/scripts/listing17-9_postcmd.sql new file mode 100644 index 0000000..ec0a987 --- /dev/null +++ b/scripts/listing17-9_postcmd.sql @@ -0,0 +1,106 @@ +spool postcmd; +set echo on; +-- Look for STATISTICS SECTION below for relevant statistics that will help +-- analyse RMAN backup performance problems +set line 2000 +alter session set nls_date_format = 'DD-MON-YYYY HH:MI:SS'; +drop table cmd_end_time; +create table cmd_end_time as select sysdate end_time from dual; +drop table post_cmd_wait_time; +drop table backup_async_io; +drop table backup_sync_io; +create table backup_async_io +as (select * from v$backup_async_io +where (sid, serial) not in (select sid, serial from pre_backup_async_io)); +-- +create table backup_sync_io +as (select * from v$backup_sync_io +where (sid, serial) not in (select sid, serial from pre_backup_sync_io)); +-- +create table post_cmd_wait_time +as select sum (time_waited_micro/1000000) time_waited_secs from v$system_event +where event like '%sbt%'; +-- +variable sbttime_in_secs number; +begin + select post.time_waited_secs - nvl(pre.time_waited_secs, 0) + into :sbttime_in_secs from pre_cmd_wait_time pre, post_cmd_wait_time post; +end; +/ +variable cmdtime_in_secs number; +begin + select (end_time - start_time)*24*60*60 into :cmdtime_in_secs + from cmd_start_time, cmd_end_time; +end; +/ +variable total_input_bytes number; +begin + select sum(bytes) into :total_input_bytes + from (select sum(bytes) bytes + from backup_async_io where type='INPUT' + union + select sum(bytes) bytes + from backup_sync_io where type='INPUT'); +end; +/ +variable total_output_bytes number; +begin + select sum(bytes) + into :total_output_bytes + from (select sum(bytes) bytes + from backup_async_io where type='OUTPUT' + union + select sum(bytes) bytes + from backup_sync_io where type='OUTPUT'); +end; +/ +variable non_sbttime_in_secs number; +begin + :non_sbttime_in_secs := :cmdtime_in_secs - :sbttime_in_secs; +end; +/ +-- STATISTICS SECTION +-- Relevant statistics that are useful to identify +-- RMAN performance problems are displayed below. +-- SBTTIME_IN_SECS is amount of time that was spent in SBT library +print sbttime_in_secs; +-- CMDTIME_IN_SECS is total command execution time +print cmdtime_in_secs; +-- NON_SBTTIME_IN_SECS is time spent in non-SBT code +print non_sbttime_in_secs; +-- TOTAL INPUT BYTES read +print total_input_bytes; +-- TOTAL OUTPUT BYTES written +print total_output_bytes; +-- Effective output bytes per second +select :total_output_bytes/:cmdtime_in_secs effective_output_bytes_per_sec + from dual; +-- Effective input bytes per second +select :total_input_bytes/:cmdtime_in_secs effective_input_bytes_per_sec + from dual; +-- Input file that is bottleneck for the backup operation +select long_waits, io_count, filename input_bottleneck_filename +from backup_async_io +where type='INPUT' +and long_waits/io_count = (select max(long_waits/io_count) + from backup_async_io where type='INPUT' ); +-- Critical I/O event information +select + pre.event, (post.total_waits-pre.total_waits) total_waits, + (post.total_timeouts-pre.total_timeouts) total_timeouts, + (post.time_waited-pre.time_waited) time_waited, + (post.time_waited_micro - pre.time_waited_micro) time_waited_micro, + (post.time_waited_micro-pre.time_waited_micro)/ + (post.total_waits-pre.total_waits) average_wait_micro +from pre_cmd_ksfq_events pre, v$system_event post +where pre.event=post.event; +-- IO_SLAVES parameter settings for the instance +show parameter io_slaves; +set line 2000 +-- Contents of V$BACKUP_ASYNC_IO generated for the RMAN command executed +select * from backup_async_io; +-- Contents of V$BACKUP_SYNC_IO generated for the RMAN command executed +select * from backup_sync_io; +-- Pre and Post command statistics for important KSFQ events +select * from v$system_event where event in ('i/o slave wait', 'io done'); +exit; diff --git a/scripts/listing17-9_precmd.sql b/scripts/listing17-9_precmd.sql new file mode 100644 index 0000000..14c4a26 --- /dev/null +++ b/scripts/listing17-9_precmd.sql @@ -0,0 +1,22 @@ +spool precmd; +set line 2000 +set echo on; +alter session set nls_date_format = 'DD-MON-YYYY HH:MI:SS'; +drop table pre_cmd_wait_time; +drop table cmd_start_time; +drop table pre_backup_sync_io; +drop table pre_backup_async_io; +drop table pre_cmd_ksfq_events; +create table pre_cmd_wait_time +as select sum (time_waited_micro/1000000) time_waited_secs +from v$system_event where event like '%sbt%'; +create table pre_backup_async_io +as select * from v$backup_async_io; +create table pre_backup_sync_io +as select * from v$backup_sync_io; +create table cmd_start_time +as select sysdate start_time from dual; +create table pre_cmd_ksfq_events +as select * from v$system_event +where event in ('i/o slave wait', 'io done'); +exit; diff --git a/scripts/listing23-3.rman b/scripts/listing23-3.rman new file mode 100644 index 0000000..9648941 --- /dev/null +++ b/scripts/listing23-3.rman @@ -0,0 +1,6 @@ +connect target / +run { + allocate channel c1 type disk connect rman/secretsauze@rman1 format '+BACKUP/%u.rmb'; + allocate channel c2 type disk connect rman/secretsauze@rman2 format '+BACKUP/%u.rmb'; + backup tablespace rmantest; +} diff --git a/scripts/listing23-4.rman b/scripts/listing23-4.rman new file mode 100644 index 0000000..1f4f530 --- /dev/null +++ b/scripts/listing23-4.rman @@ -0,0 +1,8 @@ +connect target / +run { + allocate channel c1 type disk connect rman/secretsauze@rman1; + allocate channel c2 type disk connect rman/secretsauze@rman2; + restore + (datafile 1,3,5 channel c1) + (datafile 2,4,6 channel c2); +} diff --git a/scripts/listing23-5_opt1.rman b/scripts/listing23-5_opt1.rman new file mode 100644 index 0000000..9f88880 --- /dev/null +++ b/scripts/listing23-5_opt1.rman @@ -0,0 +1,3 @@ +configure channel 1 device type 'sbt' connect 'rman/secretsauze@rman1' PARMS "ENV=(NB_ORA_CLIENT=RMAN1)"; +configure channel 2 device type 'sbt' connect 'rman/secretsauze@rman2' PARMS "ENV=(NB_ORA_CLIENT=RMAN2)"; + diff --git a/scripts/listing23-5_opt2.rman b/scripts/listing23-5_opt2.rman new file mode 100644 index 0000000..09b54b8 --- /dev/null +++ b/scripts/listing23-5_opt2.rman @@ -0,0 +1,5 @@ +run { + allocate channel c1 type sbt PARMS='ENV=(NB_ORA_CLIENT=RMAN1)' connect='rman/secretsauze@rman1'; + allocate channel c2 type sbt PARMS='ENV=(NB_ORA_CLIENT=RMAN2)' connect='rman/secretsauze@rman2'; + backup database; +} diff --git a/scripts/listing24-3.sql b/scripts/listing24-3.sql new file mode 100644 index 0000000..d51e828 --- /dev/null +++ b/scripts/listing24-3.sql @@ -0,0 +1,10 @@ +create directory rman as '+DG1/RMAN'; +create directory rmanbackup as '+DG1/RMANBACKUP'; +begin + dbms_file_transfer.copy_file ( + SOURCE_DIRECTORY_OBJECT => 'RMAN', + SOURCE_FILE_NAME => '0oniv1g8_1_1.rmb', + DESTINATION_DIRECTORY_OBJECT => 'RMANBACKUP', + DESTINATION_FILE_NAME => '0oniv1g8_1_1.new.rmb' + ); +end; \ No newline at end of file diff --git a/scripts/listing25-2_optA.rman b/scripts/listing25-2_optA.rman new file mode 100644 index 0000000..ee74f80 --- /dev/null +++ b/scripts/listing25-2_optA.rman @@ -0,0 +1,11 @@ +run { +allocate channel c1 type disk; +allocate channel c2 type disk; +allocate channel c3 type disk; +allocate channel c4 type disk; +allocate channel c5 type disk; +allocate channel c6 type disk; +allocate channel c7 type disk; +allocate channel c8 type disk; + backup database; +} \ No newline at end of file diff --git a/scripts/listing25-2_optB.rman b/scripts/listing25-2_optB.rman new file mode 100644 index 0000000..d52d1ff --- /dev/null +++ b/scripts/listing25-2_optB.rman @@ -0,0 +1,11 @@ +run { +allocate channel c1 type disk format '+ORABACK/%u.rmb'; +allocate channel c2 type disk format '+ORABACK/%u.rmb'; +allocate channel c3 type disk format '+ORABACK/%u.rmb'; +allocate channel c4 type disk format '+ORABACK/%u.rmb'; +allocate channel c5 type disk format '+ORABACK/%u.rmb'; +allocate channel c6 type disk format '+ORABACK/%u.rmb'; +allocate channel c7 type disk format '+ORABACK/%u.rmb'; +allocate channel c8 type disk format '+ORABACK/%u.rmb'; +backup database; +} \ No newline at end of file diff --git a/scripts/listing25-3_optC.rman b/scripts/listing25-3_optC.rman new file mode 100644 index 0000000..9087c94 --- /dev/null +++ b/scripts/listing25-3_optC.rman @@ -0,0 +1,11 @@ +run { +allocate channel c1 type disk format '/dwbackup1/%u.rmb'; +allocate channel c2 type disk format '/dwbackup1/%u.rmb'; +allocate channel c3 type disk format '/dwbackup1/%u.rmb'; +allocate channel c4 type disk format '/dwbackup1/%u.rmb'; +allocate channel c5 type disk format '/dwbackup1/%u.rmb'; +allocate channel c6 type disk format '/dwbackup1/%u.rmb'; +allocate channel c7 type disk format '/dwbackup1/%u.rmb'; +allocate channel c8 type disk format '/dwbackup1/%u.rmb'; + backup database; +} \ No newline at end of file diff --git a/scripts/listing25-4.sql b/scripts/listing25-4.sql new file mode 100644 index 0000000..194f883 --- /dev/null +++ b/scripts/listing25-4.sql @@ -0,0 +1,4 @@ +select set_count, sid, type, substr(filename,1,30) filename, + buffer_size, buffer_count bc, elapsed_time et, bytes +from v$backup_async_io a +where set_stamp = 793415558; \ No newline at end of file diff --git a/scripts/listing25-5.sql b/scripts/listing25-5.sql new file mode 100644 index 0000000..bfccc6d --- /dev/null +++ b/scripts/listing25-5.sql @@ -0,0 +1,9 @@ +col blocks_skipped_in_cell head 'Cell Skip' +col cell_rman_eff head 'RMAN Eff%' format 999.99 +select file#, blocks, blocks_read, datafile_blocks, blocks_skipped_in_cell, 100* blocks_skipped_in_cell/blocks_read cell_rman_eff +from v$backup_datafile +/ +select completion_time, blocks, blocks_read, datafile_blocks +used_change_tracking +from v$backup_datafile +where file# = 5;