Thursday 23 July 2015

How to catalog backups / archivelogs / datafile copies / control file copies

RMAN Catalog:It is mainly used for following:
    Can store database backup scripts and backup information to safe place(RMAN Repository)apart from target database control file.
    Can add backup pieces and image copies of backup on disk to the RMAN repository.
    Can record a data file copy as a level 0 incremental backup in the RMAN repository and that can be used foran incremental backup.
    Can record latest user-managed datafile copies to RMAN repository made after the clean shutdown of database.
Limitations and Advantages of Catalog:
To connect to target database using RMAN target database must be mounted or open.
  1. Catalog database must be OPEN if RMAN is connected to catalog database.
  2. RMAN can only catalog a datafile copy, control file copy, archived log or backup piece if these areuser-managed copy (OS level copy).
  3. Catalogis accessible on disk.
  4. File belongs to another database can not be cataloged using CATALOG.
  5. All user managed (File system) backups considered as an IMAGE COPIES by RMAN while cataloged.
  6. RMAN does not check whether the file was correctly copied by the operating system utility; it just reads and checks the header during cataloging but file should be clean(consistent) while copying through OS utilities so .
Cataloging Backups Examples:
1. Cataloging Archived Logs:Here we assumed that archive logs have been moved to other location using operating system utilities (CP/MV/COPY) and we cataloging those moved Archiveloged to RMAN REPOSITORY.
RMAN > CATALOG ARCHIVELOG ‘?/oradata/backup/arch_1.dbf’, ‘?/oradata/backup/arch_9.dbf’;
If you need to catalog multiple archive files then use below simple script which will generate .rcv file and run newly created .rcv file.
[oracle@test ~] echo > catalog.rcv for archivelog in /u01/test/arch/* ; do echo "catalog archivelog '$archivelog';" >> catalog.rcv done
Now connect to rman promt and run .rcv using below command.
[oracle@test ~] Rman target / cmdfile=catalog.rcv
2.Cataloging consistent copy of datafile as an incremental backup:Here we are cataloging datafile copy data01.dbfas an incremental level 0 backup to RMAN repository,
This datafile copy must be consistent and can be either taken by OS copy commands or by RAMN backup as copy command:
CATALOG DATAFILECOPY ‘?/oracle/oradata/data01.dbf’ LEVEL 0;
3.Cataloging controlfile copy in the RMAN Repository tken by user:
a. Take backup of controle file by using below query:
SQL> alter database backup controlfile to ‘/u01/bkp/controlfile01.dbf’;
b. Catalog above controlfile copy to RMAN REPOSITORY using blow query:
RMAN> catalog controlfilecopy ‘oracle/oradata/control01.ctl’;
4.Cataloging all the database file copies present in one Directory:
Below example will catalog all the archivelog copied using OS command to directory /u01/bkp/archlog:
RMAN> CATALOG START WITH ‘/u01/bkp/archlog’;
5.Cataloging Files in the Flash Recovery Area:Below will catalog Flash Recovery Area without prompting to user:
CATALOG RECOVERY AREA NOPROMPT;
6. Cataloging RMAN Backup Pieces:BELOW WILL CATALOG a RMAN backup piece to RMAN Repository which is manually copied using OS commands to default backup location:
CATALOG BACKUPPIECE ‘/u01/bkp/rman/KOKTSV_ORCL_RMAN_ONL_ST’;
7.Below command will catalog the Backup Pieces present in the Location set for DB_RECOVERY_FILE_DEST Parameter:
RMAN> catalog db_recovery_file_dest;
Note:catalog backuppiece, catalog recovery area, catalog start with, catalog db_recovery_file_dest commands are not available in 9i.







I hope this article helped you. Your suggestions/feedbacks are most welcome.

Keep learning... Have a great day!!!


Wednesday 15 July 2015

Oracle Baseline/ SQL plan migration to its DEV/QA/Clone

In this article I have explained step by step how to copy/migrate SQL baseline from source database to target database.

On Source database
============ 

Check the list of SQL plan baselines on Source

SQL> select SQL_HANDLE,plan_name, enabled, accepted FROM dba_sql_plan_baselines ;


SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyv0239c560 YES NO
SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyv3fc6434b YES NO
SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyvccdd3f88 YES YES


Create the staging table to hold the SQL baseline

SQL> BEGIN
DBMS_SPM.CREATE_STGTAB_BASELINE(
table_name > 'spm_staging_tab',
table_owner > 'BIASDBA',
tablespace_name > 'TOOLS');
END;



PL/SQL procedure successfully completed.
Check the baseline staging table

SQL> desc biasdba.spm_staging_tab
Name Null? Type
----------------------------------------- -------- ----------------------------
VERSION NUMBER
SIGNATURE NUMBER
SQL_HANDLE VARCHAR2(30)
OBJ_NAME VARCHAR2(30)
OBJ_TYPE VARCHAR2(30)
PLAN_ID NUMBER
SQL_TEXT CLOB
CREATOR VARCHAR2(30)
ORIGIN VARCHAR2(30)
DESCRIPTION VARCHAR2(500)
DB_VERSION VARCHAR2(64)
CREATED TIMESTAMP(6)
LAST_MODIFIED TIMESTAMP(6)
LAST_EXECUTED TIMESTAMP(6)
LAST_VERIFIED TIMESTAMP(6)
STATUS NUMBER
OPTIMIZER_COST NUMBER
MODULE VARCHAR2(64)
ACTION VARCHAR2(64)
EXECUTIONS NUMBER
ELAPSED_TIME NUMBER
CPU_TIME NUMBER
BUFFER_GETS NUMBER
DISK_READS NUMBER
DIRECT_WRITES NUMBER
ROWS_PROCESSED NUMBER
FETCHES NUMBER
END_OF_FETCH_COUNT NUMBER
CATEGORY VARCHAR2(30)
SQLFLAGS NUMBER
TASK_ID NUMBER
TASK_EXEC_NAME VARCHAR2(30)
TASK_OBJ_ID NUMBER
TASK_FND_ID NUMBER
TASK_REC_ID NUMBER
INUSE_FEATURES NUMBER
PARSE_CPU_TIME NUMBER
PRIORITY NUMBER
OPTIMIZER_ENV RAW(2000)
BIND_DATA RAW(2000)
PARSING_SCHEMA_NAME VARCHAR2(30)
COMP_DATA CLOB


Now pack the baselines / load the baselines to the staging table created above

SQL> SET SERVEROUTPUT ON
DECLARE
l_plans_packed PLS_INTEGER;
SQL> 2 3 BEGIN
4 l_plans_packed : DBMS_SPM.pack_stgtab_baseline(
table_name > 'spm_staging_tab',
5 6 table_owner > 'BIASDBA');

7 8 DBMS_OUTPUT.put_line('Plans Packed: ' || l_plans_packed);
END;
9 10 /


Plans Packed: 3
PL/SQL procedure successfully completed.

Check the baseline table after loading

SQL> select sql_handle from BIASDBA.spm_staging_tab;

SQL_HANDLE
------------------------------
SQL_172a4815a43b43db
SQL_172a4815a43b43db
SQL_172a4815a43b43db



On target database
============

Copy required table to target database.

Create the DB link to the source database ( If the DBlink not an option then use export / import to copy the baseline staging table data to target).

SQL> create public database link efipfqa1 connect to biasdba identified by biasdba using 'efipfqa1';

Check the DB link is working or not

SQL> select SQL_HANDLE from biasdba.spm_staging_tab@efipfqa1;
SQL_HANDLE
------------------------------
SQL_172a4815a43b43db
SQL_172a4815a43b43db
SQL_172a4815a43b43db


Create the baseline staging table using the source database baseline staging table data


SQL> create table biasdba.spm_staging_tab as select * from biasdba.spm_staging_tab@efipfqa1;Table created.

Now Unpack / unload the baseline to the database dictionary
SQL> SET SERVEROUTPUT ON
SQL> DECLARE
2 l_plans_unpacked PLS_INTEGER;
3 BEGIN
l_plans_unpacked : DBMS_SPM.unpack_stgtab_baseline(
4 5 table_name > 'spm_staging_tab',
6 table_owner > 'BIASDBA');

7 8 DBMS_OUTPUT.put_line('Plans Unpacked: ' || l_plans_unpacked);
9 END;
10 /


Plans Unpacked: 3
PL/SQL procedure successfully completed.

Check the baselines created from the unload operation above

SQL> select SQL_HANDLE,plan_name, enabled, accepted FROM dba_sql_plan_baselines ;

SQL_HANDLE PLAN_NAME ENA ACC
------------------------------ ------------------------------ --- ---
SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyv0239c560 YES NO
SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyv3fc6434b YES NO
SQL_172a4815a43b43db SQL_PLAN_1fak82qk3qhyvccdd3f88 YES YES






I hope this article helped you. Your suggestions/feedbacks are most welcome.
Keep learning... Have a great day!!!