دیتابیس اوراکل

دیتابیس اوراکل
طبقه بندی موضوعی

Backup and Restore ARCHIVELOG

  • BACKUP ARCHIVELOG

RMAN> backup format '/home/oracle/back/back_for_stbydf_%s_%p.back' archivelog sequence 188168 thread 2;
OR
RMAN> backup format '/home/oracle/back/back_for_stbydf_%s_%p.back' archivelog from sequence 189118 until sequence 189143 thread 2;

 

RMAN> list backup of archivelog from sequence 189118 until sequence 189143 thread 2;

 

  • RESTORE ARCHIVELOG

RMAN> catalog start with '/home/oracle/back';
RMAN> restore archivelog sequence 188168 thread 2;
OR
RMAN> restore archivelog from sequence 189118 until sequence 189143 thread 2;

Number of Transactions (per second)

WITH
    hist_snaps
    AS
        (SELECT instance_number,
                snap_id,
                ROUND (begin_interval_time, 'MI') begin_snap_time,
                ROUND (end_interval_time, 'MI') end_snap_time,
                  (  begin_interval_time
                   + 0
                   - LAG (begin_interval_time + 0)
                         OVER (PARTITION BY dbid, instance_number
                               ORDER BY snap_id))
                * 86400                              diff_time
           FROM dba_hist_snapshot),
    hist_stats
    AS
        (SELECT dbid,
                instance_number,
                snap_id,
                stat_name,
                  VALUE
                - LAG (VALUE)
                      OVER (PARTITION BY dbid, instance_number, stat_name
                            ORDER BY snap_id)    delta_value
           FROM dba_hist_sysstat
          WHERE stat_name IN ('user commits', 'user rollbacks'))
  SELECT sn.begin_snap_time,
         sn.end_snap_time,
         sn.instance_number,
         ROUND (SUM (delta_value) / 3600)     "TRANSACTIONS/S"
    FROM hist_snaps sn, hist_stats st
   WHERE st.instance_number = sn.instance_number
     AND st.snap_id = sn.snap_id
     AND sn.diff_time IS NOT NULL
     AND sn.instance_number = 1
     AND TO_CHAR (sn.end_snap_time, 'yyyy-mm-dd') = TO_CHAR (sysdate-1, 'yyyy-mm-dd')
GROUP BY sn.begin_snap_time, sn.end_snap_time, sn.instance_number
ORDER BY 1;

Restore and Recover

ORACLE_BASE=/oracle; export ORACLE_BASE
ORACLE_HOME=$ORACLE_BASE/product/11.2.0.4/db_1; export ORACLE_HOME
ORACLE_SID=TSTDB; export ORACLE_SID

RMAN>startup nomount pfile='/oracle/product/11.2.0.4/db_1/dbs/initTSTDB.ora';
RMAN>restore controlfile from '/home/oracle/TSTDB/autobackup/2021_05_15/o1_mf_s_1072634365_j9zm5p0p_.bkp';
RMAN>alter database mount;
RMAN>run {
restore database;
switch datafile all;
set until sequence 60951;
recover database;
}
RMAN> alter database open resetlogs;

Create Controlfile

ممکن است در وضعیتی قرار بگیریم که همه controlfileهای دیتابیس ما از بین رفته یا corrupt شده باشند و هیچ بکاپی هم از آنها موجود نباشد، در چنین وضعیتی باید به صورت دستی یک controlfile ایجاد کنیم. برای اینکه بتوانیم دستور CREATE CONTROLFILE را تولید کنیم، 2 حالت وحود دارد:

 

حالت اول: اگر دیتابیس هنوز در وضعیت mount یا open است، میتوانیم به صورت زیر این کار را انجام دهیم.

 

SQL> alter database backup controlfile to trace as '/home/oracle/ctl.sql';

 

در فایل ctl.sql همانطور که مشاهده میکنید، دستور CREATE CONTROLFILE به 2 صورت ایجاد شده است، یکی برای حالتی که redo log fileهای شما سالم هستند، یکی هم برای حالتی که redo log fileهای شما به هر دلیلی در دسترس نیستند و یا آسیب دیده اند. اگر redo log fileهای شما سالم هستند، در دستور CREATE CONROLFILE از عبارت NORESETLOGS استفاده کنید، که نیازی به open resetlog نباشد و دیتابیس را به صورت معمولی open کنید. در غیر اینصورت باید از عبارت RESETLOGS استفاده کنید. بسته به اینکه کدام روش را انتخاب میکنید، بقیه مراحلی هم که باید بعد از ایجاد controlfile انجام شود، در همان فایل trace آمده است.

 

حالت دوم: اگر دیتابیس در حالت mount یا open نباشد، باید دستور CREATE CONTROLFILE را خودمان تولید کنیم. یک نمونه از این دستور در زیر آمده است. در هر دیتابیس باید یک سری از موارد آن مانند نام datafileها، redo fileها و ... را تغییر دهید.

 

[oracle@bpdb01 ~]$ vi /home/oracle/create_controlfile_strings.sql

CREATE CONTROLFILE REUSE DATABASE "CDBCAT" NORESETLOGS(OR RESETLOGS)  ARCHIVELOG
    MAXLOGFILES 16
    MAXLOGMEMBERS 3
    MAXDATAFILES 1024
    MAXINSTANCES 8
    MAXLOGHISTORY 292
LOGFILE
  GROUP 1 '+DATA/CDBCAT/ONLINELOG/group_1.269.1051706207'  SIZE 600M BLOCKSIZE 512,
  GROUP 2 '+DATA/CDBCAT/ONLINELOG/group_2.270.1051706277'  SIZE 600M BLOCKSIZE 512,
  GROUP 3 '+DATA/CDBCAT/ONLINELOG/group_3.271.1051706237'  SIZE 600M BLOCKSIZE 512
DATAFILE
  '+DATA/CDBCAT/DATAFILE/system.257.1049211357',
  '+DATA/CDBCAT/DATAFILE/sysaux.265.1049211403',
  '+DATA/CDBCAT/DATAFILE/undotbs1.260.1049211429',
  '+DATA/CDBCAT/86B637B62FE07A65E053F706E80A27CA/DATAFILE/system.273.1049211811',
  '+DATA/CDBCAT/86B637B62FE07A65E053F706E80A27CA/DATAFILE/sysaux.274.1049211811',
  '+DATA/CDBCAT/DATAFILE/users.263.1049211429',
  '+DATA/CDBCAT/86B637B62FE07A65E053F706E80A27CA/DATAFILE/undotbs1.275.1049211811',
  '+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/DATAFILE/system.280.1049212669',
  '+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/DATAFILE/sysaux.281.1049212669',
  '+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/DATAFILE/undotbs1.279.1049212669',
  '+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/DATAFILE/users.283.1049212693',
  '+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/DATAFILE/rcat.317.1051270001',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/system.331.1051617437',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/sysaux.332.1051617439',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/undotbs1.330.1051617437',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/users.334.1051617457',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt.266.1051707583',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt_ecm_depot.341.1051707945',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt_deepdive.342.1051707973',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt_ad4j_ts.344.1051711033',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt_ecm_depot_ts.345.1051711035',
  '+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/DATAFILE/mgmt_tablespace.346.1051711035'
CHARACTER SET AL32UTF8;

 

نکته 1: اگر لیست دیتافایل ها را نداشته باشیم، میتوانیم به صورت زیر از controlfile که corrupt شده بدست آوریم: 

SQL> select name from v$controlfile;

NAME
--------------------------------------------------------------------------------
+DATA/P01LIVE/CONTROLFILE/current.483.1082170095

 

ASMCMD> cp +DATA/P01LIVE/CONTROLFILE/current.483.1082170095 /home/oracle

[oracle@bpdb01 ~]$ strings /home/oracle/current.483.1082170095 > /tmp/controlfile_info.txt

[oracle@bpdb01 ~]$ more /tmp/controlfile_info.txt

در فایل controlfile_info.txt لیست دیتافایل ها وجود دارند. فقط دقت داشته باشید که ممکن است نام بعضی از دیتافایل ها تکراری باشد.

 

بعد از اینکه فایل CREATE CONTROLFILE را تولید کردیم، باید مراحل زیر را انجام دهیم تا دیتابیس استارت شود:

SQL> startup nomount;

SQL> @/home/oracle/create_controlfile_strings.sql

 

For NORESETLOGS:

SQL> RECOVER DATABASE;

SQL> ALTER SYSTEM ARCHIVE LOG ALL;

SQL> ALTER DATABASE OPEN;

SQL> ALTER PLUGGABLE DATABASE ALL OPEN;

 

For RESETLOGS:

SQL> RECOVER DATABASE USING BACKUP CONTROLFILE;

SQL> ALTER DATABASE OPEN RESETLOGS;

SQL> ALTER PLUGGABLE DATABASE ALL OPEN;

 

SQL> ALTER SESSION SET CONTAINER = "CDB$ROOT";

SQL> ALTER TABLESPACE TEMP ADD TEMPFILE 
'+DATA/CDBCAT/TEMPFILE/temp.272.1049211509' SIZE 138412032  REUSE AUTOEXTEND ON NEXT 655360  MAXSIZE 32767M;

SQL> ALTER SESSION SET CONTAINER = "PDB$SEED";
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE 
'+DATA/CDBCAT/AD8A912FC7D0E1F5E0534302A8C0A045/TEMPFILE/temp.276.1049211841' SIZE 37748736  REUSE AUTOEXTEND ON NEXT 655360  MAXSIZE 32767M;

SQL> ALTER SESSION SET CONTAINER = "CATPDB";
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE 
'+DATA/CDBCAT/AD8AC2769AE8EE31E0534302A8C08077/TEMPFILE/temp.282.1049212675' SIZE 37748736  REUSE AUTOEXTEND ON NEXT 655360  MAXSIZE 32767M;

SQL> ALTER SESSION SET CONTAINER = "EMPDB";
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE 
'+DATA/CDBCAT/AFBAA9CC33AA4DF6E0534302A8C0858D/TEMPFILE/temp.333.1051617443' SIZE 77594624  REUSE AUTOEXTEND ON NEXT 655360  MAXSIZE 32767M;

 

 

Document:

Doc ID 735106.1

http://www.vinayagaconsultancyltd.co.uk/blogs/rman/recovering-from-loss-of-controlfile

 

Data Guard Physical Standby Switchover using SQLPlus

  1. Verify Managed Recovery is running on the standby:

On Standby:

SQL> select process from v$managed_standby where process like 'MRP%';

PROCESS

-------------

MRP0

 

On Primary:

SQL> select recovery_mode from v$archive_dest_status where dest_id=2;

RECOVERY_MODE

-------------------------------------

MANAGED REAL TIME APPLY

 

  1. Verify there are no Gaps:

On Primary: 
select a.db_unique_name , a.dest_name ,a.archived_seq# ,  a.applied_seq#, a.gap_status 
  from v$archive_dest_status a
 where a.db_unique_name in ('stby_dbunique');

 

select thread#, max(sequence#) "Last Primary Seq Generated"
from gv$archived_log val, gv$database vdb
where val.resetlogs_change# = vdb.resetlogs_change#
group by thread# order by 1;

 

On Standby:
select thread#, max(sequence#) "Last Standby Seq Applied"
from gv$archived_log val, gv$database vdb
where val.resetlogs_change# = vdb.resetlogs_change#
and val.applied in ('YES')
group by thread# order by 1;

 

select thread#, low_sequence#, high_sequence# from v$archive_gap;

 

  1. Verify all datafiles are online On Target Standby:

SQL> select name from v$datafile where status='OFFLINE';

If there are any OFFLINE datafiles, and these are needed after switchover, bring them ONLINE:

SQL> alter database datafile '<DATAFILE_NAME>' online;

 

  1. Verify Primary and Standby tempfiles match:

select tmp.name filename, bytes, ts.name tablespace
  from v$tempfile tmp, v$tablespace ts
 where tmp.ts#=ts.ts#;

If the queries do not match, then you can correct the mismatch now or immediately after the open of the new primary database;

 

  1. Stop Jobs in Primary

SQL> select * from dba_jobs_running;

Depending on what the running job is, be ready to terminate the job if necessary.

 

Block further job submission by setting the job_queue_processes parameter to 0 so that there would be no jobs running during switchover.

SQL> show parameter job_queue_processes

SQL> alter system set job_queue_processes=0 scope=spfile;

 

  1. Create Guaranteed Restore Points

On Standby:

SQL> alter database recover managed standby database cancel;

SQL> create restore point SWITCHOVER_START_GRP guarantee flashback database;

SQL> alter database recover managed standby database using current logfile nodelay disconnect from session;

 

On Primary: 

SQL> create restore point SWITCHOVER_START_GRP guarantee flashback database;

 

  1. Verify that the primary database can be switched to the standby role.

SQL> select switchover_status from v$database;

SWITCHOVER_STATUS

-----------------------------

SESSIONS ACTIVE

A value of TO STANDBY or SESSIONS ACTIVE (which requires the WITH SESSION SHUTDOWN clause on the switchover command) indicates that the primary database can be switched to the standby role.

 

Switchover always originates from Primary database. On the request of switchover sql statement "alter database commit to switchover to physical standby with session shutdown", Primary will generate special marker called EOR (end-of-redo) that is placed in the header of online redo log sequence. So this online redo log sequence will be archived locally and sent to all standby databases. Only upon receiving and applying EOR (end-of-redo), v$database.switchover_status will change from "not allowed" to "to primary" or "sessions active". At this stage Physical standby is ready to assume Primary database role.

  1. If The Primary is a RAC, then shutdown all secondary primary instances
  2. Switchover the Primary to a standby database

SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO STANDBY WITH SESSION SHUTDOWN;

 

  1. Verify that the standby database can be switched to the primary role.

SQL> select switchover_status from v$database;

SWITCHOVER_STATUS

----------------------------

TO PRIMARY

A value of TO PRIMARY or SESSIONS ACTIVE indicates that the standby database is ready to be switched to the primary role.

 

  1. Switchover the Standby to a primary

SQL> ALTER DATABASE COMMIT TO SWITCHOVER TO PRIMARY WITH SESSION SHUTDOWN;

SQL> ALTER DATABASE OPEN;

 

  1. Restart the new standby

SQL> shutdown immediate;

SQL> startup mount;

SQL> alter database recover managed standby database using current logfile disconnect;

SQL> alter database open;

If the database is a RAC, then start all secondary instances on the new standby.

 

  1. Check Primary and New Standby:

SQL> select db_unique_name,total_gap,open_mode,database_role from v$database;

 

  1. Drop any Switchover Guaranteed Restore Points on all databases.

DGMGRL> drop restore point SWITCHOVER_START_GRP;

 

  1. Reset Jobs

Set the job queue processes to its original value on the new standby.

SQL> alter system set job_queue_processes=<value> scope=both sid='*';

SQL> show parameter job_queue_processes

 

Document:

Doc ID 1304939.1

 

ORA-16792: configurable property value is inconsistent with database setting

DGMGRL> show configuration

Configuration - dgmgrl_base1

  Protection Mode: MaxPerformance

    base1    - Physical standby database
    Warning: ORA-16792: configurable property value is inconsistent with database setting

 


DGMGRL> show database 'base1' 'InconsistentProperties';
INCONSISTENT PROPERTIES
   INSTANCE_NAME     PROPERTY_NAME         MEMORY_VALUE       SPFILE_VALUE           BROKER_VALUE
   BASE1                     DbFileNameConvert                                       +DATA,+DATA2         +DATA,+DATA2
   BASE1                     LogFileNameConvert                                      +DATA,+DATA2         +DATA,+DATA2

 

 

 

Duplicate a controlfile in ASM

1. Identify the location of the current controlfile:

SQL> select name from v$controlfile;

NAME
--------------------------------------------------------------------------------
+DATA2/archgrd/controlfile/current.268.1000399643

 

2. Stop the Database and startup in nomount state:

SQL> shut immediate;

SQL> startup nomount;

 

3. Use RMAN to duplicate the controlfile:

RMAN> restore controlfile to '+DATA' from '/+DATA2/archgrd/controlfile/current.268.1000399643';

 

4.Show Location Of New Control Files:

$ asmcmd
ASMCMD> find --type controlfile . *
+DATA/ARCHGRD/CONTROLFILE/current.920.1072880265
+DATA2/ARCHGRD/CONTROLFILE/current.268.1000399643

 

5. On the database:

SQL> alter system set

control_files='+DATA2/ARCHGRD/CONTROLFILE/current.268.1000399643','+DATA/ARCHGRD/CONTROLFILE/current.920.1072880265' scope=spfile;

SQL> shut immediate;

SQL> startup;

 

6. Verify that new control file has been recognized:

SQL> select name from v$controlfile;

NAME
--------------------------------------------------------------------------------
+DATA2/archgrd/controlfile/current.268.1000399643
+DATA/archgrd/controlfile/current.920.1072880265

 

 

 

Data Guard Broker Configuration

Primary: arch

Standby: archgrd

 

  1. In primary & Standby

SQL> alter system set dg_broker_start=true;

 

  1. In primary

DGMGRL> connect sys

DGMGRL> CREATE CONFIGURATION dgmgrl_arch AS PRIMARY DATABASE IS arch CONNECT IDENTIFIER IS arch;

DGMGRL> ADD DATABASE archgrd AS CONNECT IDENTIFIER IS archgrd MAINTAINED AS PHYSICAL;

DGMGRL> ENABLE CONFIGURATION;

DGMGRL> SHOW CONFIGURATION;

DGMGRL> SHOW DATABASE arch;

DGMGRL> SHOW DATABASE archgrd;

 

Set a Property in DGMGRL

Oracle DB Version = 11.2

 

DGMGRL> edit database BASE1 set property DbFileNameConvert = '';
Property "dbfilenameconvert" updated

ِData Guard Physical Standby Switchover using the Broker

1. Verify there are no Gaps:

Primary: 
select thread#, max(sequence#) "Last Primary Seq Generated"
from gv$archived_log val, gv$database vdb
where val.resetlogs_change# = vdb.resetlogs_change#
group by thread# order by 1;

 

Physical Stby:
select thread#, max(sequence#) "Last Standby Seq Applied"
from gv$archived_log val, gv$database vdb
where val.resetlogs_change# = vdb.resetlogs_change#
and val.applied in ('YES')
group by thread# order by 1;

 

Primary: 
select a.db_unique_name , a.dest_name ,a.archived_seq# ,  a.applied_seq#, a.gap_status 
  from v$archive_dest_status a
 where a.db_unique_name in ('BASE1');

 

Physical Stby:

select thread#, low_sequence#, high_sequence# from v$archive_gap;

 

2. Verify all datafiles are online On Target Standby:

SQL> select name from v$datafile where status='OFFLINE';

 

If there are any OFFLINE datafiles, and these are needed after switchover, bring them ONLINE:

SQL> alter database datafile '<DATAFILE_NAME>' online;

 

3. Verify Primary and Standby tempfiles match:

select tmp.name filename, bytes, ts.name tablespace
  from v$tempfile tmp, v$tablespace ts
 where tmp.ts#=ts.ts#;

 

If the queries do not match, then you can correct the mismatch now or immediately after the open of the new primary database;

 

4. Stop Jobs in Primary

SQL> select * from dba_jobs_running;

Depending on what the running job is, be ready to terminate the job if necessary.

 

Block further job submission by setting the job_queue_processes parameter to 0 so that there would be no jobs running during switchover.

SQL> show parameter job_queue_processes

SQL> alter system set job_queue_processes=0 scope=spfile;

 

5. Create Guaranteed Restore Points

 Physical Stby:

SQL> alter database recover managed standby database cancel;

SQL> create restore point SWITCHOVER_START_GRP guarantee flashback database;

SQL> alter database recover managed standby database using current logfile nodelay disconnect from session parallel 10;

 

Primary: 

SQL> create restore point SWITCHOVER_START_GRP guarantee flashback database;

 

6. Check the primary database:

DGMGRL> show database verbose 'primary_dbunique';

 

7. Check the standby database that is the target of the switchover:

DGMGRL> show database verbose 'standby_dbunique';

 

8. Issue the switchover command:

DGMGRL> switchover to 'standby_dbunique';

Switchover always originates from Primary database. On the request of switchover sql statement "alter database commit to switchover to physical standby with session shutdown", Primary will generate special marker called EOR (end-of-redo) that is placed in the header of online redo log sequence. So this online redo log sequence will be archived locally and sent to all standby databases. Only upon receiving and applying EOR (end-of-redo), v$database.switchover_status will change from "not allowed" to "to primary" or "sessions active". At this stage Physical standby is ready to assume Primary database role.

 

9. Show the configuration:

DGMGRL> show configuration;

 

10. Check Primary and Standby:

SQL> select db_unique_name,total_gap,open_mode,database_role from v$database;

 

11. Drop any Switchover Guaranteed Restore Points on all databases.

DGMGRL> drop restore point SWITCHOVER_START_GRP;

 

 

Document:

https://docs.oracle.com/cd/E11882_01/server.112/e40771/sofo.htm#DGBKR330

Doc ID 1305019.1