测试在 Oracle 下直接 rm dbf 数据文件并重启数据库

2023年 12月 12日 66.8k 0

创建一个新的表空间并创建新的用户,指定新表空间为新用户的默认表空间

create tablespace zzw datafile '/oradata/cesdb/zzw01.dbf' size 10m;

zzw用户已经创建过,这里修改其默认表空间

alter user zzw quota unlimited on zzw;
alter user zzw default tablespace zzw;

创建一个简单的测试表

CREATE TABLE t1 (
id INT NOT NULL,
name VARCHAR(50),
);

INSERT INTO t1 (id, name) VALUES (1, 'Alice');
INSERT INTO t1 (id, name) VALUES (2, 'Bob');
INSERT INTO t1 (id, name) VALUES (3, 'Charlie');
INSERT INTO t1 (id, name) VALUES (4, 'David');
INSERT INTO t1 (id, name) VALUES (5, 'Emily');

insert into t1 select * from t1;
insert into t1 select * from t1;
insert into t1 select * from t1;

SQL> select count(*) from t1;

接下来创建给表空间添加新的数据文件并插入数据

alter tablespace zzw add datafile '/oradata/cesdb/zzw02.dbf ' size 1m;
select file_id,file_name,bytes/1024/1024 from dba_data_files where tablespace_name='ZZW';

SQL> insert into t1 select * from t1;

10240 rows created.

SQL> insert into t1 select * from t1;

20480 rows created.

SQL> insert into t1 select * from t1;

40960 rows created.

SQL> insert into t1 select * from t1;

81920 rows created.

SQL> insert into t1 select * from t1;

163840 rows created.

SQL> insert into t1 select * from t1;
insert into t1 select * from t1
*
ERROR at line 1:
ORA-01653: unable to extend table ZZW.T1 by 128 in tablespace ZZW

现在删除数据文件

$ mv /oradata/cesdb/zzw02.dbf /oradata/cesdb/zzw02.dbf_bak

再次插入数据显示已经找不到dbf数据库文件了

SQL> insert into t1 select * from t1;
insert into t1 select * from t1
*
ERROR at line 1:
ORA-01116: error in opening database file 6
ORA-01110: data file 6: '/oradata/cesdb/zzw02.dbf '
ORA-27041: unable to open file
Linux-x86_64 Error: 2: No such file or directory
Additional information: 3

这时连shutdown immediate关库都关不掉了

SQL> shutdown immediate
ORA-01116: error in opening database file 6
ORA-01110: data file 6: '/oradata/cesdb/zzw02.dbf '
ORA-27041: unable to open file
Linux-x86_64 Error: 2: No such file or directory
Additional information: 3

只能用 shutdown abort 关闭数据库了

SQL> shutdown abort
ORACLE instance shut down.

因为数据文件丢失启动数据库只能起到mount状态

SQL> startup
ORACLE instance started.

Total System Global Area 3240239104 bytes
Fixed Size 2257600 bytes
Variable Size 2030046528 bytes
Database Buffers 1191182336 bytes
Redo Buffers 16752640 bytes
Database mounted.
ORA-01157: cannot identify/lock data file 6 - see DBWR trace file
ORA-01110: data file 6: '/oradata/cesdb/zzw02.dbf '

然后先 offline 这个数据文件再打开数据库

SQL> alter database datafile 6 offline;

Database altered.

SQL> alter database open;

Database altered.

重建数据文件的语法

SQL> alter database create datafile 6;

Database altered.

#or
#alter database create datafile '//oradata/cesdb/zzw02.dbf' [as '/oradata/cesdb/zzw02.dbf'];

recover 恢复数据文件

SQL> recover datafile 6;
Media recovery complete.

online 数据文件

alter database datafile 6 online;

查看数据文件是否onilne

SQL> select file#,status from v$datafile_header where file#=6;

FILE# STATUS
---------- ----------
6 ONLINE

SQL> select COUNT(*) from t1;

COUNT(*)
----------
327708

相关文章

Oracle如何使用授予和撤销权限的语法和示例
Awesome Project: 探索 MatrixOrigin 云原生分布式数据库
下载丨66页PDF,云和恩墨技术通讯(2024年7月刊)
社区版oceanbase安装
Oracle 导出CSV工具-sqluldr2
ETL数据集成丨快速将MySQL数据迁移至Doris数据库

发布评论