标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 kfed MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 Oracle 恢复 ORACLE恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (102)
- 数据库 (1,682)
- DB2 (22)
- MySQL (73)
- Oracle (1,544)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (159)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (7)
- Oracle ASM (67)
- Oracle Bug (8)
- Oracle RAC (53)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (565)
- Oracle安装升级 (92)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (79)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (27)
- SQL Server恢复 (8)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- 断电引起的ORA-08102: 未找到索引关键字, 对象号 39故障处理
- ORA-00227: corrupt block detected in control file
- 手工删除19c rac
- 解决oracle数据文件路径有回车故障
- .wstop扩展名勒索数据库恢复
- Oracle Recovery Tools工具一键解决ORA-00376 ORA-01110故障(文件offline)
- OGG-02771 Input trail file format RELEASE 19.1 is different from previous trail file form at RELEASE 11.2.
- OGG-02246 Source redo compatibility level 19.0.0 requires trail FORMAT 12.2 or higher
- GoldenGate 19安装和打patch
- dd破坏asm磁盘头恢复
- 删除asmlib磁盘导致磁盘组故障恢复
- Kylin Linux 安装19c
- ORA-600 krse_arc_complete.4
- Oracle 19c 202410补丁(RUs+OJVM)
- ntfs MFT损坏(ntfs文件系统故障)导致oracle异常恢复
- .mkp扩展名oracle数据文件加密恢复
- 清空redo,导致ORA-27048: skgfifi: file header information is invalid
- A_H_README_TO_RECOVER勒索恢复
- 通过alert日志分析客户自行对一个数据库恢复的来龙去脉和点评
- ORA-12514: TNS: 监听进程不能解析在连接描述符中给出的SERVICE_NAME
标签归档:ORA-03262
删除Oracle数据文件/临时文件
有些时候,想删除一个数据文件(临时文件),在10g之前的版本,要删除一个数据文件,必须删除该数据文件所属的表空间(特殊处理方法除外)。不太懂数据库的朋友直接os级别删除数据文件,导致数据库不能正常启动;稍微等点数据库的朋友,会先offline数据文件,然后os级别删除,但是这条数据文件的记录还保留在数据字典中,不爽(特殊处理办法见:清除离线数据文件记录)。在10g及其以后版本中,oracle提供了alter tablespace talbespace_name drop datafile/tempfile path/file_id进行删除某个数据文件
一、删除数据文件
[oracle@ECP-UC-DB1 ~]$ sqlplus / as sysdba SQL*Plus: Release 10.2.0.4.0 - Production on Thu Dec 8 11:22:38 2011 Copyright (c) 1982, 2007, Oracle. All Rights Reserved. Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SQL> col tablespace_name for a20 SQL> col file_name for a50 SQL> set line 120 SQL> select file_id,file_name,tablespace_name 2 from dba_data_files order by tablespace_name; FILE_ID FILE_NAME TABLESPACE_NAME ---------- -------------------------------------------------- -------------------- 9 /opt/oracle/oradata/test/odu01.dbf ODU 10 /opt/oracle/oradata/test/odu03.dbf ODU 8 /opt/oracle/oradata/test/odu02.dbf ODU 3 /opt/oracle/oradata/test/sysaux01.dbf SYSAUX 1 /opt/oracle/oradata/test/system01.dbf SYSTEM 2 /opt/oracle/oradata/test/undotbs01.dbf UNDOTBS1 5 /opt/oracle/oradata/test/user32g.dbf USERS 7 /opt/oracle/oradata/test/user02.dbf USERS 4 /opt/oracle/oradata/test/users01.dbf USERS 6 /opt/oracle/oradata/test/xifenfei01.dbf XFF 11 /opt/oracle/oradata/test/xifenfei03.dbf XFF 11 rows selected. SQL> !ls -l /opt/oracle/oradata/test/*.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 8 00:05 /opt/oracle/oradata/test/odu01.dbf -rw-r----- 1 oracle oinstall 11282685952 Dec 8 00:05 /opt/oracle/oradata/test/odu02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/odu03.dbf -rw-r----- 1 oracle oinstall 387981312 Dec 8 12:36 /opt/oracle/oradata/test/sysaux01.dbf -rw-r----- 1 oracle oinstall 534781952 Dec 8 12:45 /opt/oracle/oradata/test/system01.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 7 22:01 /opt/oracle/oradata/test/temp01.dbf -rw-r----- 1 oracle oinstall 1289756672 Dec 8 12:45 /opt/oracle/oradata/test/undotbs01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/user02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/user32g.dbf -rw-r----- 1 oracle oinstall 5251072 Dec 8 00:05 /opt/oracle/oradata/test/users01.dbf -rw-r----- 1 oracle oinstall 20979712 Dec 8 00:05 /opt/oracle/oradata/test/xifenfei01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/xifenfei03.dbf SQL> alter tablespace xff drop datafile 11; alter tablespace xff drop datafile 11 * ERROR at line 1: ORA-03262: the file is non-empty SQL> col segment_name for a20 SQL> select owner,SEGMENT_NAME,FILE_ID,BLOCKS from dba_extents 2 where file_id=11; OWNER SEGMENT_NAME FILE_ID BLOCKS ------------------------------ -------------------- ---------- ---------- CHF XFF_TEST 11 8 CHF XFF_TEST 11 128 CHF XFF_TEST 11 128 CHF T_XFF 11 128 CHF T_XFF 11 128 SQL> alter table chf.xff_test move tablespace users; Table altered. SQL> alter table chf.t_xff move tablespace users; Table altered. SQL> select owner,SEGMENT_NAME,FILE_ID,BLOCKS from dba_extents 2 where file_id=11; no rows selected SQL> alter tablespace xff drop datafile 11; Tablespace altered. SQL> select file_id,file_name,tablespace_name 2 from dba_data_files order by tablespace_name; FILE_ID FILE_NAME TABLESPACE_NAME ---------- -------------------------------------------------- -------------------- 9 /opt/oracle/oradata/test/odu01.dbf ODU 10 /opt/oracle/oradata/test/odu03.dbf ODU 8 /opt/oracle/oradata/test/odu02.dbf ODU 3 /opt/oracle/oradata/test/sysaux01.dbf SYSAUX 1 /opt/oracle/oradata/test/system01.dbf SYSTEM 2 /opt/oracle/oradata/test/undotbs01.dbf UNDOTBS1 4 /opt/oracle/oradata/test/users01.dbf USERS 7 /opt/oracle/oradata/test/user02.dbf USERS 5 /opt/oracle/oradata/test/user32g.dbf USERS 6 /opt/oracle/oradata/test/xifenfei01.dbf XFF 10 rows selected. SQL> !ls -l /opt/oracle/oradata/test/*.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 8 00:05 /opt/oracle/oradata/test/odu01.dbf -rw-r----- 1 oracle oinstall 11282685952 Dec 8 00:05 /opt/oracle/oradata/test/odu02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/odu03.dbf -rw-r----- 1 oracle oinstall 387981312 Dec 8 12:36 /opt/oracle/oradata/test/sysaux01.dbf -rw-r----- 1 oracle oinstall 534781952 Dec 8 12:45 /opt/oracle/oradata/test/system01.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 7 22:01 /opt/oracle/oradata/test/temp01.dbf -rw-r----- 1 oracle oinstall 1289756672 Dec 8 12:45 /opt/oracle/oradata/test/undotbs01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:52 /opt/oracle/oradata/test/user02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:52 /opt/oracle/oradata/test/user32g.dbf -rw-r----- 1 oracle oinstall 5251072 Dec 8 12:52 /opt/oracle/oradata/test/users01.dbf -rw-r----- 1 oracle oinstall 20979712 Dec 8 12:52 /opt/oracle/oradata/test/xifenfei01.dbf
二、删除临时表空间文件
SQL> alter tablespace temp add tempfile '/opt/oracle/oradata/test/xff_temp02.dbf' size 10m; Tablespace altered. SQL> select file_id,file_name,tablespace_name from dba_temp_files; FILE_ID FILE_NAME TABLESPACE_NAME ---------- -------------------------------------------------- -------------------- 2 /opt/oracle/oradata/test/xff_temp02.dbf TEMP 1 /opt/oracle/oradata/test/temp01.dbf TEMP SQL> !ls -l /opt/oracle/oradata/test/*.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 8 00:05 /opt/oracle/oradata/test/odu01.dbf -rw-r----- 1 oracle oinstall 11282685952 Dec 8 00:05 /opt/oracle/oradata/test/odu02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/odu03.dbf -rw-r----- 1 oracle oinstall 387981312 Dec 8 13:00 /opt/oracle/oradata/test/sysaux01.dbf -rw-r----- 1 oracle oinstall 534781952 Dec 8 12:58 /opt/oracle/oradata/test/system01.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 7 22:01 /opt/oracle/oradata/test/temp01.dbf -rw-r----- 1 oracle oinstall 1289756672 Dec 8 12:57 /opt/oracle/oradata/test/undotbs01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:57 /opt/oracle/oradata/test/user02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:57 /opt/oracle/oradata/test/user32g.dbf -rw-r----- 1 oracle oinstall 5251072 Dec 8 12:57 /opt/oracle/oradata/test/users01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 13:00 /opt/oracle/oradata/test/xff_temp02.dbf -rw-r----- 1 oracle oinstall 20979712 Dec 8 12:57 /opt/oracle/oradata/test/xifenfei01.dbf SQL> alter tablespace temp drop tempfile 2; Tablespace altered. SQL> !ls -l /opt/oracle/oradata/test/*.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 8 00:05 /opt/oracle/oradata/test/odu01.dbf -rw-r----- 1 oracle oinstall 11282685952 Dec 8 00:05 /opt/oracle/oradata/test/odu02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 00:05 /opt/oracle/oradata/test/odu03.dbf -rw-r----- 1 oracle oinstall 387981312 Dec 8 13:00 /opt/oracle/oradata/test/sysaux01.dbf -rw-r----- 1 oracle oinstall 534781952 Dec 8 12:58 /opt/oracle/oradata/test/system01.dbf -rw-r----- 1 oracle oinstall 104865792 Dec 7 22:01 /opt/oracle/oradata/test/temp01.dbf -rw-r----- 1 oracle oinstall 1289756672 Dec 8 12:57 /opt/oracle/oradata/test/undotbs01.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:57 /opt/oracle/oradata/test/user02.dbf -rw-r----- 1 oracle oinstall 10493952 Dec 8 12:57 /opt/oracle/oradata/test/user32g.dbf -rw-r----- 1 oracle oinstall 5251072 Dec 8 12:57 /opt/oracle/oradata/test/users01.dbf -rw-r----- 1 oracle oinstall 20979712 Dec 8 12:57 /opt/oracle/oradata/test/xifenfei01.dbf
三、注意事项
1、Oracle Database 10g Release 2及其以上版本
2、删除数据文件从数据库和系统
3、数据文件必须为空
4、数据文件不是对应表空间的最后一个
5、不能删除只读表空间中数据文件
6、不能删除system中数据文件
7、不能删除本地管理的offline表空间数据文件