offline tablespace 的几种方式 | |||||||||||
想要offline tablespace有以下三种方式: OFFLINE {NORMAL | TEMPORARY | IMMEDIATE} 其中,normal是默认的。 下面通过测试说明几种情况的异同: ----offline normal: idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841678 1416800082 idle>alter tablespace test_increment offline normal; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841750 1416841750 1416800082 ----offline normal,tablespace内所有的数据文件上触发checkpoint。 checkpoint_change#增加。 idle>alter tablespace test_increment online; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841783 1416841750 ----online时,不需要media recovery,同时tablespace内所有的数据文件上再次触发checkpoint。 checkpoint_change#增加。 ----offline temporary: idle>alter tablespace test_increment offline temporary; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841826 1416841826 1416841750 idle>alter tablespace test_increment online; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841836 1416841750 ----证明了文档中的如下说法: ----If no files are offline, but you use the temporary option, media recovery is not required to bring the tablespace back online. ----offline immediate: idle>alter tablespace test_increment offline immediate; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841836 1416841875 1416841750 ----offline immediate,tablespace内所有的数据文件上不触发checkpoint。 checkpoint_change#不变。 idle>alter tablespace test_increment online; alter tablespace test_increment online * ERROR 位于第 1 行: ORA-01113: ?? 3 ?????? ORA-01110: ???? 3: 'D:ORA92ORADATAORACLETEST_INCREMENT01.DBF' ----将tablespace online 时需要media recovery。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841836 1416841875 1416841750 idle>recover datafile 3; 完成介质恢复。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841875 1416841875 1416841750 idle>alter tablespace test_increment online; 表空间已更改。 idle>select checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ------------------ ------------ --------------- 1416841912 1416841750 ----online时,tablespace内所有的数据文件上再次触发checkpoint。 checkpoint_change#增加。 ---为了更清楚的说明offline temporary,我们新加一数据文件。 idle>alter tablespace test_increment add datafile 2 'd:ora92oradataoracletest_increment02.dbf' size 5m; 表空间已更改。 idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842065 1416842037 4 1416842189 0 idle>alter database datafile 3 offline; 数据库已更改。 idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842065 1416842321 1416842037 4 1416842189 0 ---单个的offline数据文件,checkpoint_change#不变。 idle>alter tablespace test_increment offline temporary; 表空间已更改。 idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842065 1416842321 1416842037 4 1416842351 1416842351 0 ---对照之前的checkpoint,可以发现:offline temporary只对那些online的数据文件进行checkpoint,而且在将tablespace online 的时候,那些进行过checkpoint的数据文件将不需要media recovery(下面可以看出)。 idle>alter session set nls_language=american; Session altered. idle>alter tablespace test_increment online; alter tablespace test_increment online * ERROR at line 1: ORA-01113: file 3 needs media recovery ORA-01110: data file 3: 'D:ORA92ORADATAORACLETEST_INCREMENT01.DBF' ----将tablespace online 的时候,那些进行过checkpoint的数据文件将不需要media recovery idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842065 1416842321 1416842037 4 1416842351 1416842351 0 idle>recover datafile 3; Media recovery complete. idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842321 1416842321 1416842037 4 1416842351 1416842351 0 idle>alter tablespace test_increment online; Tablespace altered. idle>select file#,checkpoint_change#,last_change#,offline_change# from v$datafile where ts#=14; FILE# CHECKPOINT_CHANGE# LAST_CHANGE# OFFLINE_CHANGE# ---------- ------------------ ------------ --------------- 3 1416842448 1416842037 4 1416842448 0 Oracle 文档的解释: Taking Tablespaces OfflineYou may want to take a tablespace offline for any of the following reasons:
When a tablespace is taken offline, Oracle takes all the associated files offline. The SYSTEM tablespace can never be taken offline. You can specify any of the following options when taking a tablespace offline:
Specify TEMPORARY only when you cannot take the tablespace offline normally. In this case, only the files taken offline because of errors need to be recovered before the tablespace can be brought online. Specify IMMEDIATE only after trying both the normal and temporary options. The following example takes the users tablespace offline normally: ALTER TABLESPACE users OFFLINE NORMAL; Before taking an online tablespace offline, consider taking the following actions:
|