二、Standby database 的建立
Oracle Standby Database 的建立过程并不复杂,但建立过程的相关设置取决于建立standby database 的目的。
例如,假如建立standby database 是为了 disaster protection,standby database 就不能建立在与 primary database 相同服务器上面。假如是为了 protection against data corruption,在standby database 接收到 primary database 送来的 archived log files 时,apply 需要晚上一段,比如三个小时,或是六个小时。这样当 primary database出现错误的时候,standby database 不会与primary database 同步。
在这篇文章里面,我无法面面俱到的分析各种性能,仅做一个具体实例分析。
我们承诺客户的条件:
24x7 uptime of SIS database
in case of failure on primary:
1.1 1/2 hour to fail over to standby database
1.2 no more than 5 mins data loss
1.3 2 hours scheduled downtime to revert back to primary/standby configuration
我们为了完成以上各项,必须完成的工作:
1. 在remote site 建立 standby database。我们有半小时的时间 activing standby database,我个人喜欢再做一次 cold backup。
2. 以我们的环境,4组 log groups,每组 2 个members,on-line redo log file size 是 10M,运行高峰期,每分钟可以多达 10 个archived files 产生。因此非高峰的时候,我们用cron job 做强制 log switch.
3. 因为我们的standby database server 不是专用的,所以在非高峰期时我们需要重新建立 primary/standby database.
在这里,我又要说一些多余的话了。DBA 在申请down time 的时候,应该给自己预留足够的时间,到底多少合适,自己要把握好。(假如留的时间太少,老板和客户可能会认为DBA的工作很轻易,或不重要,假如一旦出了差错,自己的压力方面也够大。所以一般选择在用户可接受的最多的时间,我一般要求需要时间的2-4倍) 。
1. 根据上面的条件,我们做的环境设置
(1) 首先我们必须确认 primary database 处于archived mode:
SQL archive log list;
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /oradba/sisi/arch
Oldest online log sequence 4783
Next log sequence to archive 4786
Current log sequence 4786
(2) 我们必须满足的条件是 high availablity,所以我们采用的是双机。
采用双机形式,有很多的好处,除了再安装与primary node 相同的OS系统及oracle 系统外,其他各种设置都可以与primary node 完全相同,省掉很多修改参数的麻烦之处。
(3) 我们的oracle 版本是8.1.7EE,standby node 通过net8 接收 primary node 的 archived log files。我们专门在 standby node 开通了 port 1512 做为 standby database 的listener。(Oracle 的缺省是 port 1521) 。
2. standby database的建立过程:
standby database一般是用primary database的cold backup建立的。非凡情况下,可以用RMAN或eXPort dmp file来做。这里我们是讲的正常情况。
(1) 在 standby node上面建立与primary node上面相同的datafile Directory。我们用的是/oradba/sisi/
(2) 修改 primary database的 initialize parameter file: (我们的例子,请不要问我为什么,很多是 application要求的,不是我制定的)
primary database:
db_name = sisi
instance_name = sisi
service_names = sisi
control_files = (/oradba/sisi/ctrl/stctl1si.ctl, /oradba/sisi/ctrl/stctl2si.ctl)
db_files = 500
compatible = 8.1.7.0.0
rollback_segments = (rbs1, rbs2, rbs3, rbs4, rbs5, rbs6, rbs7, rbs8, rbs9, rbs10, rbs11, rbs12, rbs1
3, rbs14, rbs15)
db_file_multiblock_read_count = 32
optimizer_mode = rule #application required
db_block_size = 8192
db_block_buffers = 83200
shared_pool_size = 52428800
sort_area_size = 1048576
sort_area_retained_size = 64000
log_checkpoint_interval = 10000
sessions = 252
transactions = 280
transactions_per_rollback_segment = 4
processes = 800
open_cursors = 1000
dml_locks = 500
log_buffer = 20971520
log_checkpoint_timeout = 10000
cursor_space_for_time = true
utl_file_dir=/tmp
timed_statistics = false # if you want timed statistics
max_dump_file_size = 2097152 # limit trace file size to 5 Meg each
core_dump_dest = /oradba/sisi/cdump
background_dump_dest= /oradba/sisi/bdump
user_dump_dest = /oradba/sisi/udump
remote_login_passWordfile = none
parallel_max_servers = 0
#The following parameters are the HA parameters needed for Standby Database on primary side
LOG_ARCHIVE_START=TRUE
LOG_ARCHIVE_FORMAT = "sisi%S.arc"
LOG_ARCHIVE_DEST_1='LOCATION=/oradba/sisi/arch MANDATORY REOPEN=60'
LOG_ARCHIVE_DEST_STATE_1=ENABLE
STANDBY_ARCHIVE_DEST='/oradba/sisi/arch'
LOG_ARCHIVE_DEST_2='SERVICE=standby_sisi MANDATORY REOPEN=60'
LOG_ARCHIVE_DEST_STATE_2=ENABLE
LOG_ARCHIVE_MIN_SUCCEED_DEST=2
复制到Standby database side相对的directory下面:
db_name = sisi
instance_name = sisi
service_names = sisi
control_files = (/oradba/sisi/ctrl/stctl1si.ctl, /oradba/sisi/ctrl/stctl2si.ctl)
db_files = 500
compatible = 8.1.7.0.0
rollback_segments = (rbs1, rbs2, rbs3, rbs4, rbs5, rbs6, rbs7, rbs8, rbs9, rbs10, rbs11, rbs12, rbs1
3, rbs14, rbs15)
db_file_multiblock_read_count = 32
optimizer_mode = rule
db_block_size = 8192
db_block_buffers = 83200
shared_pool_size = 52428800
sort_area_size = 1048576 #100M Change to 1M after import.
sort_area_retained_size = 64000
log_checkpoint_interval = 10000
sessions = 252
transactions = 280
transactions_per_rollback_segment = 4
processes = 800
open_cursors = 1000
dml_locks = 500
log_buffer = 20971520
log_checkpoint_timeout = 10000
cursor_space_for_time = true
utl_file_dir=/tmp
timed_statistics = false # if you want timed statistics
max_dump_file_size = 2097152 # limit trace file size to 5 Meg each
core_dump_dest = /oradba/sisi/cdump
background_dump_dest= /oradba/sisi/bdump
user_dump_dest = /oradba/sisi/udump
remote_login_passwordfile = none
parallel_max_servers = 0
#The following parameter are the HA parameters needed for Standby Database on standby side
LOG_ARCHIVE_START=FALSE
LOG_ARCHIVE_FORMAT = "sisi%S.arc"
LOG_ARCHIVE_DEST_1='LOCATION=/oradba/sisi/arch MANDATORY REOPEN=60'
LOG_ARCHIVE_DEST_STATE_1=ENABLE
STANDBY_ARCHIVE_DEST='/oradba/sisi/arch'
LOG_ARCHIVE_DEST_2='SERVICE=standby_sisi MANDATORY REOPEN=60'
LOG_ARCHIVE_DEST_STATE_2=ENABLE
LOG_ARCHIVE_MIN_SUCCEED_DEST=2
(3) shutdown primary database normal/immediate,做一个冷备份,再次 startup primary database时,用 pfile标示到上面改过的 parameter file. 用FTP或其他OS工具,把冷备份的 data
files/online redo log files到在standby node已经建好的对应 directory下面。
(4) 建立 standby database control file.
Alter database create standby controlfile as ‘/oradba/sisi/temp/stctl1si.ctl’;
用 rcp或 ftp到standby node对应的directory,用 cp command复制另一个。
(5) 在primary side编辑 tnsnames.ora文件,增加一条(可以用netasst做):
STANDBY_SISI =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 172.19.26.10)(PORT = 1512))
)
(CONNECT_DATA =
(SID = sisi)
)
)
(6) 在 standby node编辑 listener.ora文件,增加一条(可以用netasst做):
ST_LISTENER =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = prtltest)(PORT = 1512))
)
SID_LIST_ST_LISTENER =
(SID_LIST =
(SID_DESC =
(GLOBAL_DBNAME = sisi)
(ORACLE_HOME = /oracle/8.1.7)
(SID_NAME = sisi)
)
)
(7) start standby li