标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-00742 ORA-01110 ORA-01555 ORA-01578 ORA-01595 ORA-08103 ORA-600 2131 ORA-600 2662 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)
- 操作系统 (103)
- 数据库 (1,740)
- DB2 (22)
- MySQL (75)
- Oracle (1,590)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (161)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (54)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (582)
- Oracle安装升级 (95)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (84)
- PostgreSQL (27)
- pdu工具 (5)
- PostgreSQL恢复 (9)
- SQL Server (29)
- SQL Server恢复 (10)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- ORA-600 krhpfh_03-1208
- VMware勒索加密恢复(vmdk勒索恢复)
- ORA-39773: parse of metadata stream failed故障处理
- sql数据库备份失败—失败: 23(数据错误(循环冗余检查)
- vmdk文件被加密恢复(虚拟机文件加密)
- 差点被误操作的ORA-600 kcratr_nab_less_than_odr故障
- win平台19c 打patch遭遇2个小问题汇总
- pg单个数据库目录恢复-pdu恢复单个数据库目录数据
- pg删除数据恢复—pdu恢复pg delete数据
- .[OnlyBuy@cyberfear.com].REVRAC勒索mysql恢复
- 表dml操作权限授权给public,导致只读用户失效
- 21c数据库恢复遭遇ora-600 ktugct: corruption detected
- pg_control丢失/损坏处理
- 当前主流数据库版本服务支持周期-202503
- pg启动报invalid checkpoint record处理
- 删除redo导致ORA-00313 ORA-00312故障处理
- Navicat连接postgresql时出现column “datlastsysoid” does not exist错误解决
- aix磁盘损坏oracle数据库恢复
- pg误删除数据恢复(PostgreSQL delete数据恢复)
- PostgreSQL表文件损坏恢复—pdu恢复损坏的表文件
标签归档:段头坏块
segment header异常对象删除处理
对于某些极端情况下,segment header出现损坏的对象该如何处理,这里通过一个实验来说明这类情况该如何处理,创建表并查询相关segment信息
SQL> create tablespace t_xff datafile '/u01/app/oracle/oradata/orcl/t_xifenfei01.dbf' size 128M autoextend on; Tablespace created. SQL> create table t_xifenfei tablespace t_xff as select * from dba_objects; Table created. SQL> select header_file,header_block from dba_SEGMENTS where segment_name='T_XIFENFEI' and owner='SYS'; HEADER_FILE HEADER_BLOCK ----------- ------------ 5 130 ----segment header 为 file 5,block 130 SQL> select EXTENT_ID , FILE_ID ,BLOCK_ID from dba_extents where segment_name='T_XIFENFEI' and owner='SYS'; EXTENT_ID FILE_ID BLOCK_ID ---------- ---------- ---------- 0 5 128 1 5 136 2 5 144 3 5 152 4 5 160 5 5 168 6 5 176 7 5 184 8 5 192 9 5 200 10 5 208 11 5 216 12 5 224 13 5 232 14 5 240 15 5 248 16 5 256 17 5 384 18 5 512 19 5 640 20 5 768 21 5 896 22 5 1024 23 5 1152 24 5 1280 25 rows selected. ---有25个extent信息 SQL> select * from dba_free_space where file_id=5; TABLESPACE_NAME FILE_ID BLOCK_ID BYTES BLOCKS ------------------------------ ---------- ---------- ---------- ---------- RELATIVE_FNO ------------ T_XFF 5 1408 122683392 14976 5 --空闲block是从1408开始
模拟segment header损坏(通过dd破坏block)
SQL> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. SQL> SQL> SQL> SQL> exit Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production With the Partitioning, OLAP, Data Mining and Real Application Testing options [oracle@xifenfei ~]$ [oracle@xifenfei ~]$ [oracle@xifenfei ~]$echo xifenfei.com|dd of=/u01/app/oracle/oradata/orcl/t_xifenfei01.dbf bs=8192 conv=notrunc seek=130 0+1 records in 0+1 records out 17 bytes (17 B) copied, 5.4389e-05 s, 313 kB/s [oracle@xifenfei ~]$ dbv file=/u01/app/oracle/oradata/orcl/t_xifenfei01.dbf DBVERIFY: Release 11.2.0.4.0 - Production on Wed Apr 13 20:29:41 2022 Copyright (c) 1982, 2011, Oracle and/or its affiliates. All rights reserved. DBVERIFY - Verification starting : FILE = /u01/app/oracle/oradata/orcl/t_xifenfei01.dbf Page 130 is marked corrupt Corrupt block relative dba: 0x01400082 (file 5, block 130) Bad header found during dbv: Data in bad block: type: 119 format: 7 rdba: 0x65666978 last change scn: 0x632e.6965666e seq: 0x6f flg: 0x6d spare1: 0x77 spare2: 0x2e spare3: 0x0 consistency value in tail: 0xada72301 check value in block header: 0xf30a computed block checksum: 0x5eb9 DBVERIFY - Verification complete Total Pages Examined : 16384 Total Pages Processed (Data) : 1234 Total Pages Failing (Data) : 0 Total Pages Processed (Index): 0 Total Pages Failing (Index): 0 Total Pages Processed (Other): 154 Total Pages Processed (Seg) : 0 Total Pages Failing (Seg) : 0 Total Pages Empty : 14995 Total Pages Marked Corrupt : 1 Total Pages Influx : 0 Total Pages Encrypted : 0 Highest block SCN : 6466979 (0.6466979)
查询表数据报错
[oracle@xifenfei ~]$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.4.0 Production on Wed Apr 13 20:29:48 2022 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to an idle instance. SQL> startup ORACLE instance started. Total System Global Area 734892032 bytes Fixed Size 2256872 bytes Variable Size 452984856 bytes Database Buffers 276824064 bytes Redo Buffers 2826240 bytes Database mounted. Database opened. SQL> select count(1) from t_xifenfei; select count(1) from t_xifenfei * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 5, block # 130) ORA-01110: data file 5: '/u01/app/oracle/oradata/orcl/t_xifenfei01.dbf'
查询extent信息为空
SQL> select EXTENT_ID , FILE_ID ,BLOCK_ID from dba_extents where segment_name='T_XIFENFEI' and owner='SYS'; no rows selected SQL> select header_file,header_block from dba_SEGMENTS where segment_name='T_XIFENFEI' and owner='SYS'; HEADER_FILE HEADER_BLOCK ----------- ------------ 5 130 SQL> select * from dba_free_space where file_id=5; TABLESPACE_NAME FILE_ID BLOCK_ID BYTES BLOCKS ------------------------------ ---------- ---------- ---------- ---------- RELATIVE_FNO ------------ T_XFF 5 1408 122683392 14976 5
尝试删除表报错
SQL> drop table t_xifenfei; drop table t_xifenfei * ERROR at line 1: ORA-01578: ORACLE data block corrupted (file # 5, block # 130) ORA-01110: data file 5: '/u01/app/oracle/oradata/orcl/t_xifenfei01.dbf'
通过加purge删除成功
SQL> drop table t_xifenfei purge; Table dropped.
删除表成功,但是磁盘空间未释放,通过查询确认变为一个临时段
SQL> select * from dba_free_space where file_id=5; TABLESPACE_NAME FILE_ID BLOCK_ID BYTES BLOCKS ------------------------------ ---------- ---------- ---------- ---------- RELATIVE_FNO ------------ T_XFF 5 1408 122683392 14976 5 SQL> select segment_name,segment_type,owner from dba_segments where header_file=5; SEGMENT_NAME -------------------------------------------------------------------------------- SEGMENT_TYPE OWNER ------------------ ------------------------------ 5.130 TEMPORARY SYS
清理临时段,彻底删除segment header异常对象删除后遗症
SQL> exec dbms_space_admin.segment_corrupt('T_XFF',5,130); PL/SQL procedure successfully completed. SQL> exec dbms_space_admin.segment_drop_corrupt('T_XFF',5,130); PL/SQL procedure successfully completed. SQL> exec DBMS_SPACE_ADMIN.TABLESPACE_REBUILD_BITMAPS ('T_XFF'); PL/SQL procedure successfully completed. SQL> select segment_name,segment_type,owner from dba_segments where header_file=5; no rows selected SQL> select * from dba_free_space where file_id=5; TABLESPACE_NAME FILE_ID BLOCK_ID BYTES BLOCKS ------------------------------ ---------- ---------- ---------- ---------- RELATIVE_FNO ------------ T_XFF 5 128 133169152 16256 5