Wednesday, January 7, 2015

Refresh activity step through RMAN

Refresh activity step through RMAN

Refresh activity from PRODUCTION to TEST
Environment Detail:
Database Name
OA_TEST
OA_PROD
Oracle Version
10.2.0.4.0(EE)
10.2.0.4.0(EE)
Server Name
TEST
PROD

Method :    RMAN DUPLICATE command
1. Check the database size of PRODUCTION database.
select sum(bytes/1024/1024/1024) "DB Physical Size(GB)" from dba_data_files;

2. Check the availability of disk on TEST environment.
Note: If sufficient space available then proceed otherwise raise request to linux/unix team

3.  Check connectivity on TEST environment
E.g check TNSPING PROD, RMAN CATALOG

4. Take full backup of TEST environment.
E.g Cold backup/EXP full/EXPDP full

5. Match the user of TEST environment with the PRODUCTION Environment.
Note: If user same for both TEST and PROD Environment, then proceed further.
If USER are different take backup of TEST database user separately with expdp.
select count(*) from dba_users;

6.  Keep the list of user password of TEST Enviroment.
Use in 10g database:
----------------------------
select 'Alter user '||username||' identified by  values '''||password||''' Default tablespace '||DEFAULT_TABLESPACE||' TEMPORARY TABLESPACE ' ||TEMPORARY_TABLESPACE||' '||case when account_status= 'OPEN' then ';' else 'LOCKED;' end from dba_users;
Use the command in 11g database:
--------------------------------------------------
select 'Alter user '||a.username||' identified by  values '''||b.password||''' Default tablespace '||DEFAULT_TABLESPACE||' TEMPORARY TABLESPACE ' ||TEMPORARY_TABLESPACE||' '||case when account_status= 'OPEN' then ';' else 'LOCKED;' end from dba_users a,sys.user$ b where b.name = a.username;
For check the password in our environment :
·         Go to bdump destination of the database.
·         Run cd..
·         cd scripts/rman
·         username we need to check the script of back
·         There are two hidden files which have password for the catalog and database.
7.  Check RMAN connectivity :
rman catalog user/password@rman target username/password@OA_PROD auxiliary /

If connected then save below in duprman.sh file:

rman catalog username/password@rman target username/password@OA_PROD auxiliary / cmdfile duprefresh.rcv log duprefresh.log

8. Make duprefresh.rcv command file:
Go to production database run the following script
Change the location in replace function according to test. It will give you all datafiles detail.

select ‘set newname for datafile ‘||file#||’ to ”’||
replace(name,’/local/data/oracle/PROD/datafiles/’,'/data10/oradata/TEST/’)||”’;’ from v$datafile ;
E.g :


run {

set until time "to_date('2013/02/20 03:25:30','yyyy/mm/dd HH24:MI:SS')";

allocate auxiliary channel C1 device type 'sbt_tape';

allocate auxiliary channel C2 device type 'sbt_tape';

allocate auxiliary channel C3 device type 'sbt_tape';

allocate auxiliary channel C4 device type 'sbt_tape';

set newname for datafile 1 to '/u02/oradata/OA_TEST/data/system1.dbf';

set newname for datafile 2 to '/u02/oradata/OA_TEST/data/system2.dbf';

set newname for datafile 3 to '/u02/oradata/OA_TEST/data/system3.dbf';

set newname for datafile 4 to '/u02/oradata/OA_TEST/data/system4.dbf';

set newname for datafile 5 to '/u02/oradata/OA_TEST/data/system5.dbf';

set newname for datafile 6 to '/u02/oradata/OA_TEST/data/system6.dbf';

set newname for datafile 7 to '/u02/oradata/OA_TEST/data/system7.dbf';

set newname for datafile 8 to '/u02/oradata/OA_TEST/data/system8.dbf';

set newname for datafile 9 to '/u02/oradata/OA_TEST/data/system9.dbf';

set newname for datafile 10 to '/u02/oradata/OA_TEST/data/appl_data1.dbf';

set newname for datafile 11 to '/u02/oradata/OA_TEST/data/appl_data2.dbf';

send 'NB_ORA_SERV=PolicyName,NB_ORA_CLIENT=ServerName';

duplicate target database to OA_TEST

logfile '/u02/oradata/OA_TEST/data/redo01.log' size 1000m,

'/u02/oradata/OA_TEST/data/redo02.log' size 1000m,

'/u02/oradata/OA_TEST/data/redo03.log' size 1000m,

'/u02/oradata/OA_TEST/data/redo04.log' size 1000m;

}

9. Run the duprman.sh command to start the activity.
10. Track the duprman.log file.
11. After restore completed change the database id.
nid target=/

12. Restore the user passwords according to TEST environment;
13. register in rman catalog with following command:
rman> register database;

EXECUTION PLAN

EXECUTION PLAN


What is execution plan ?


To run a DML statement, Oracle might need to perform many steps. Each of these steps either retrieves rows of data physically from the database or prepares them in some way for the user issuing the statement. The combination of the steps Oracle uses to run a statement is called an execution plan. An execution plan includes an access method for each table that the statement accesses and an ordering of the tables (the join order). The steps of the execution plan are not performed in the order in which they are numbered.


How to generate execution plan ?


There are three ways to view execution plan

1. Through AUTOTRACE

SQL> set autotrace trace exp
SQL> select * from emp;

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=3 Card=14 Bytes=51
8)

1 0 TABLE ACCESS (FULL) OF 'EMP' (TABLE) (Cost=3 Card=14 Bytes
=518)


2. Through DBMS_XPLAN package

SQL> explain plan for select * from emp;

Explained.

SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------

Plan hash value: 3956160932

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 14 | 518 | 3 (0)| 00:00:01 |
| 1 | TABLE ACCESS FULL| EMP | 14 | 518 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------

8 rows selected.

3. Through trace file (trace event 10046,sql_trace=true) and format trace file through TKPROF utility.

10046 trace event

10046 trace event


What is 10046 trace events


whenever we want to tune any sql statement and want to know about waits and bind variable ...then we can use 10046 trace events.


How to use 10046 trace events


First define trace identifier for generated trace files so we can easily identify our trace files in UDUMP folder.

SQL> alter session set tracefile_identifier='MYSESSION';

Enable 10046 tracing.

SQL> alter session set events '10046 trace name context forever, level 8';

Now execute SQL Statements...

select e.empno, e.ename, d.dname, d.deptno
from emp e , dept d
where e.deptno = d.deptno;

Disable 10046 tracing.

SQL> alter session set events '10046 trace name context off';

Check UDUMP directory for generated trace file.
file name like "XXXX_MYSESSION.TRC"

C:\Oracle\admin\ora9i\udump>dir *MYSESSION.trc

Now generated trace file is RAW trace file and very hard to read and understand ...so through TKPROF utility create readable output file for generated trace file.

C:\Oracle\admin\ora9i\udump>tkprof ORA01904_MYSESSION.TRC c:\output.log

TKPROF: Release 10.1.0.5.0 - Production on Wed Oct 17 19:01:44 2007

Copyright (c) 1982, 2005, Oracle. All rights reserved.

Open c:\output.log file and analyze it. below is content of output.log file

select e.empno, e.ename, d.dname, d.deptno
from emp e , dept d
where e.deptno = d.deptno


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.29 0.31 2 0 2 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.00 3 30 2 14
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.29 0.31 5 30 4 14


Misses in library cache during parse: 1
Optimizer mode: CHOOSE
Parsing user id: 66


---Below is execution plan

Rows Row Source Operation
------- ---------------------------------------------------
14 NESTED LOOPS
14 TABLE ACCESS FULL EMP
14 TABLE ACCESS BY INDEX ROWID DEPT
14 INDEX UNIQUE SCAN (object id 32119)


---Waits time information.


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 2 0.00 0.00
db file sequential read 3 0.00 0.00
SQL*Net message from client 2 56.49 56.51



10046 Trace Level


Level 1
Basic trace level. Like the standard SQL_TRACE trace file. Provides statistics for parse, execute, fetch, commit and rollback database calls.

Level 4
Displays bind variables

Level 8
Displays wait statistics

Level 12
Displays wait statistics and bind variables

Autotrace in SQLPLUS

Autotrace in SQLPLUS


What is AUTOTRACE


In SQL*Plus you can automatically get a report on the execution path used by the SQL optimizer and the statement execution statistics. The report is generated after a successful SQL DML statement, such as SELECT, DELETE, UPDATE or INSERT. It is useful for monitoring and tuning the performance of these DML statements.


How to configure AUTOTRACE in SQLPLUS for database user


1. Change directory path and connect with SYSTEM user to database
C:\>cd c:\oracle\product\10.1.0\db_1\rdbms\admin

C:\Oracle\product\10.1.0\Db_1\RDBMS\ADMIN>sqlplus /nolog

SQL*Plus: Release 9.0.1.0.1 - Production on Tue Oct 16 17:08:20 2007

(c) Copyright 2001 Oracle Corporation. All rights reserved.

SQL> conn system/manager
Connected.

2. run UTLXPLAN.SQL script for plan table.
SQL> @utlxplan.sql

3. Create public synonym for plan table or grant all privilege.
SQL> create public synonym plan_table for plan_table;

SQL> grant all on plan_table to public;

Grant succeeded.

4. Exit and again change directory path and connect with SYS user to database
SQL> exit
Disconnected from Oracle9i Enterprise Edition Release 9.0.1.1.1 - Production
With the Partitioning option
JServer Release 9.0.1.1.1 - Production

C:\Oracle\product\10.1.0\Db_1\RDBMS\ADMIN>cd\

C:\>cd c:\oracle\product\10.1.0\db_1\sqlplus\admin

C:\Oracle\product\10.1.0\Db_1\sqlplus\admin>sqlplus /nolog

SQL*Plus: Release 9.0.1.0.1 - Production on Tue Oct 16 17:12:07 2007

(c) Copyright 2001 Oracle Corporation. All rights reserved.

SQL> conn sys as sysdba
Enter password:
Connected.

5. run plustrce script and script must be run with SYS user.
SQL> @plustrce
SQL>
SQL> drop role plustrace;

Role dropped.

SQL> create role plustrace;

Role created.

SQL>
SQL> grant select on v_$sesstat to plustrace;

Grant succeeded.

SQL> grant select on v_$statname to plustrace;

Grant succeeded.

SQL> grant select on v_$mystat to plustrace;

Grant succeeded.

SQL> grant plustrace to dba with admin option;

Grant succeeded.

SQL> set echo off

6. Grant plustrace role to public.
SQL> grant plustrace to public;

Grant succeeded.


Configuring the Autotrace Report


SET AUTOTRACE OFF - No AUTOTRACE report is generated. This is the
default.
SET AUTOTRACE ON EXPLAIN - The AUTOTRACE report shows only the optimizer
execution path.
SET AUTOTRACE ON STATISTICS - The AUTOTRACE report shows only the SQL
statement execution statistics.
SET AUTOTRACE ON - The AUTOTRACE report includes both the
optimizer execution path and the SQL
statement execution statistics.
SET AUTOTRACE TRACEONLY - Like SET AUTOTRACE ON, but suppresses the
printing of the user's query output, if any.


Database Statistics for SQL Statements


recursive calls
Number of recursive calls generated at both the user and system level. Oracle maintains tables used for internal processing. When Oracle needs to make a change to these tables, it internally generates an internal SQL statement, which in turn generates a recursive call.

db block gets
Number of times a CURRENT block was requested.

consistent gets
Number of times a consistent read was requested for a block.

physical reads
Total number of data blocks read from disk. This number equals the value of "physical reads direct" plus all reads into buffer cache.

redo size
Total amount of redo generated in bytes.

bytes sent via SQL*Net to client
Total number of bytes sent to the client from the foreground processes.

bytes received via SQL*Net from client
Total number of bytes received from the client over Oracle Net.

SQL*Net roundtrips to/from client
Total number of Oracle Net messages sent to and received from the client.

sorts (memory)
Number of sort operations that were performed completely in memory and did not require any disk writes.

sorts (disk)
Number of sort operations that required at least one disk write.

rows processed
Number of rows processed during the operation.


EXAMPLE


SQL> set autotrace on
SQL> select * from dept;

DEPTNO DNAME LOC
---------- -------------- -------------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 TABLE ACCESS (FULL) OF 'DEPT'




Statistics
----------------------------------------------------------
0 recursive calls
2 db block gets
2 consistent gets
0 physical reads
0 redo size
702 bytes sent via SQL*Net to client
503 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
4 rows processed

SQL> set autotrace traceonly
SQL> select * from dept;


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 TABLE ACCESS (FULL) OF 'DEPT'




Statistics
----------------------------------------------------------
0 recursive calls
2 db block gets
2 consistent gets
0 physical reads
0 redo size
702 bytes sent via SQL*Net to client
503 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
4 rows processed

SQL> set autotrace trace explain
SQL> select * from dept;

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE
1 0 TABLE ACCESS (FULL) OF 'DEPT'



SQL> set autotrace trace statistics
SQL> select * from dept;


Statistics
----------------------------------------------------------
0 recursive calls
2 db block gets
2 consistent gets
0 physical reads
0 redo size
702 bytes sent via SQL*Net to client
503 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
4 rows processed