月归档:三月 2015

通过bbed修改obj$中dataobj$重现I_OBJ4索引报ORA-08102错误

在最近的数据库恢复中,经历了多次11.2库由于各种原因,数据库打开后,报ORA-8102错误,而且错误对象是OBJ$上的I_OBJ4这个index上,而且不能创建新表,周末开会闲着无事,进行了一个简单的模拟重现
数据库版本信息11.2.0.4

SQL> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
PL/SQL Release 11.2.0.4.0 - Production
CORE    11.2.0.4.0      Production
TNS for Linux: Version 11.2.0.4.0 - Production
NLSRTL Version 11.2.0.4.0 - Production

定位需要破坏的OBJ$上记录,为了使之和I_OBJ4中记录不一致,从而实现ORA-8102错误

SQL> select object_id,object_type from dba_objects where object_name='I_OBJ4';

 OBJECT_ID OBJECT_TYPE
---------- -------------------
     87404 INDEX

SQL> select max(DATAOBJ#) from obj$;

MAX(DATAOBJ#)
-------------
        87420

SQL> select dump(87420,16) from dual;

DUMP(87420,16)
-----------------------
Typ=2 Len=4: c3,9,4b,15

SQL> select dbms_rowid.rowid_relative_fno(rowid) file#,dbms_rowid.rowid_block_number(rowid) block#,
dbms_rowid.rowid_row_number(rowid) row#
  2    3  from obj$ where DATAOBJ#=87420;

     FILE#     BLOCK#       ROW#
---------- ---------- ----------
         1      98085         40

SQL>  alter system dump datafile 1  block 98085;

System altered.

SQL>  select value from v$diag_info where name='Default Trace File';

VALUE
--------------------------------------------------------------------------------
/u01/app/oracle/diag/rdbms/xifenfei/xifenfei/trace/xifenfei_ora_26373.trc

--dump该记录显示
tab 0, row 40, @0x11fc
tl: 72 fb: --H-FL-- lb: 0x0  cc: 18
col  0: [ 2]  c1 02
col  1: [ 4]  c3 09 4b 15
col  2: [ 1]  80
col  3: [12]  5f 4e 45 58 54 5f 4f 42 4a 45 43 54
col  4: [ 2]  c1 02
col  5: *NULL*
col  6: [ 1]  80
col  7: [ 7]  78 71 08 18 0c 26 24
col  8: [ 7]  78 73 03 0d 15 2e 2b
col  9: [ 7]  78 71 08 18 0c 26 24
col 10: [ 1]  80
col 11: *NULL*
col 12: *NULL*
col 13: [ 1]  80
col 14: *NULL*
col 15: [ 1]  80
col 16: [ 4]  c3 07 38 24
col 17: [ 1]  80
tab 0, row 41, @0x9af
tl: 2 fb: --HDFL-- lb: 0x2

这里我们知道i_obj4中的dataobj#最大值为87420对应的16进制记录为04 c3 09 4b 15

使用bbed破坏记录,修改dataobj#中的值,使得obj$.dataobj#和i_obj4中的dataobj#不匹配

SQL> select name from v$datafile where file#=1;

NAME
--------------------------------------------------------------------------------
/u01/app/oracle/oradata/xifenfei/system01.dbf


SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.


[oracle@localhost ~]$ bbed blocksize=8192 mode=edit filename='/u01/app/oracle/oradata/xifenfei/system01.dbf'
Password: 

BBED: Release 2.0.0.0.0 - Limited Production on Sat Mar 14 14:23:02 2015

Copyright (c) 1982, 2011, Oracle and/or its affiliates.  All rights reserved.

************* !!! For Oracle Internal Use only !!! ***************

BBED> show all
        FILE#           0
        BLOCK#          1
        OFFSET          0
        DBA             0x00000000 (0 0,1)
        FILENAME        /u01/app/oracle/oradata/xifenfei/system01.dbf
        BIFILE          bifile.bbd
        LISTFILE       
        BLOCKSIZE       8192
        MODE            Edit
        EDIT            Unrecoverable
        IBASE           Dec
        OBASE           Dec
        WIDTH           80
        COUNT           512
        LOGFILE         log.bbd
        SPOOL           No

BBED> set block 98085
        BLOCK#          98085
BBED> p *kdbr[40]
rowdata[2446]
-------------
ub1 rowdata[2446]                           @4696     0x2c


BBED> x /rnnncnnncc
rowdata[2446]                               @4696    
-------------
flag@4696: 0x2c (KDRHFL, KDRHFF, KDRHFH)
lock@4697: 0x00
cols@4698:   18

col    0[2] @4699: 1 
col    1[4] @4702: 87420 
col    2[1] @4707: 0 
col   3[12] @4709: _NEXT_OBJECT
col    4[2] @4722: 1 
col    5[0] @4725: *NULL*
col    6[1] @4726: 0 
col    7[7] @4728: xq...&$
col    8[7] @4736: xs....+
col    9[7] @4744: xq...&$
col   10[1] @4752: .
col   11[0] @4754: *NULL*
col   12[0] @4755: *NULL*
col   13[1] @4756: .
col   14[0] @4758: *NULL*
col   15[1] @4759: .
col   16[4] @4761: Ã.8$
col   17[1] @4766: .


BBED> set block 98085
        BLOCK#          98085

BBED> set offset 4702
        OFFSET          4702

BBED> set count 32
        COUNT           32

BBED> d
 File: /u01/app/oracle/oradata/xifenfei/system01.dbf (0)
 Block: 98085            Offsets: 4702 to 4733           Dba:0x00000000
------------------------------------------------------------------------
 04c3094b 1501800c 5f4e4558 545f4f42 4a454354 02c102ff 01800778 7108180c 

 <32 bytes per line>

BBED> set offset +4
        OFFSET          4706

BBED> d
 File: /u01/app/oracle/oradata/xifenfei/system01.dbf (0)
 Block: 98085            Offsets: 4706 to 4737           Dba:0x00000000
------------------------------------------------------------------------
 1501800c 5f4e4558 545f4f42 4a454354 02c102ff 01800778 7108180c 26240778 

 <32 bytes per line>

BBED> m /x 17 
 File: /u01/app/oracle/oradata/xifenfei/system01.dbf (0)
 Block: 98085            Offsets: 4706 to 4737           Dba:0x00000000
------------------------------------------------------------------------
 1701800c 5f4e4558 545f4f42 4a454354 02c102ff 01800778 7108180c 26240778 

 <32 bytes per line>

BBED> sum apply
Check value for File 0, Block 98085:
current = 0xd361, required = 0xd361

BBED> verify
DBVERIFY - Verification starting
FILE = /u01/app/oracle/oradata/xifenfei/system01.dbf
BLOCK = 98085


DBVERIFY - Verification complete

Total Blocks Examined         : 1
Total Blocks Processed (Data) : 1
Total Blocks Failing   (Data) : 0
Total Blocks Processed (Index): 0
Total Blocks Failing   (Index): 0
Total Blocks Empty            : 0
Total Blocks Marked Corrupt   : 0
Total Blocks Influx           : 0
Message 531 not found;  product=RDBMS; facility=BBED

使用bbed 修改04 c3 09 4b 15为04 c3 09 4b 17

重现在obj$的I_OBJ4 index上报ORA-8102错误,而且不能创建新对象

SQL> startup
ORACLE instance started.

Total System Global Area 1570009088 bytes
Fixed Size                  2253584 bytes
Variable Size             469765360 bytes
Database Buffers         1090519040 bytes
Redo Buffers                7471104 bytes
Database mounted.
Database opened.

SQL> create table t1 as select * from dba_users;
create table t1 as select * from dba_users
                                 *
ERROR at line 1:
ORA-00604: error occurred at recursive SQL level 1
ORA-08102: index key not found, obj# 87404, file 1, block 97266 (2)

SQL> col OBJECT_NAME for a30
SQL> select object_name,object_type from dba_objects where object_id=87404;

OBJECT_NAME                    OBJECT_TYPE
------------------------------ -------------------
I_OBJ4                         INDEX

如果修复该问题请见:使用bbed 修复I_OBJ4 index 报ORA-8102

发表在 Oracle | 标签为 , , , | 评论关闭

注意系统bug—linux在E5、E5 V2、E7 V2 cpu之上的bug 765720

今天晚上群里面兄弟说了一个linux 6上面bug,会导致系统在运行200天以上(hardware uptime),然后进行热重启后,可能在几分钟或者几个小时内出发该bug,导致系统异常.

主要影响条件为:
Red Hat Enterprise Linux 6.1 (kernel-2.6.32-131.26.1.el6 and newer)
Red Hat Enterprise Linux 6.2 (kernel-2.6.32-220.4.2.el6 and newer)
Red Hat Enterprise Linux 6.3 (kernel-2.6.32-279 series)
Red Hat Enterprise Linux 6.4 (kernel-2.6.32-358 series)
Any Intel® Xeon® E5, Intel® Xeon® E5 v2, or Intel® Xeon® E7 v2 series processor
从这里可以看出来该问题主要影响E5、E5 V2、E7 V2 cpu上的redhat 6.1-6.4版本,在6.5版本中修复,具体参考:bug 765720
另外对已ORACLE Linux,如果使用EL Kernel影响和redhat一致,如果使用Unbreakable Enterprise Kernel则在6.2版本中进行了修复该问题。
MOS上类似文章:Oracle Linux 6 RHCK system hang: processes blocked in ext4_file_open(), pick_next_task_fair()

补充说明:
1. 在Red Hat/OEL 5.x版本中不存在。
2. 在32和64位操作系统都有可能发生
3. 鉴于该bug短期内无法修复,而且真的发生了,考虑冷重启主机,临时规避

再次提醒:系统版本选定也很重要,大家在选择Linux版本之时尽量选择避开该bug(el kernel 6.5及其以后版本,uek kernel 6.2及其以后版本)。个人倾向:如果是部署ORACLE db,而且还是redhat系列Linux,更加倾向OEL(省事,相信Oracle)

发表在 Linux | 评论关闭

ORACLE 12C 新特性Identity Columns—实现ORACLE自增长列功能

在ORACLE 12C以前的版本中,如果要实现列自增长,需要通过序列+触发器实现,到了12C ORACLE 引进了Identity Columns新特性,从而实现了列自增长功能,和mysql,sql server类似功能.
使用语法
ORACLE 12C IDENTITY
GENERATED ALWAYS AS IDENTITY方式测试

C:\Users\ffcheng>sqlplus chf/xifenfei@pdb

SQL*Plus: Release 12.1.0.2.0 Production on 星期二 3月 10 14:34:46 2015

Copyright (c) 1982, 2014, Oracle.  All rights reserved.

上次成功登录时间: 星期五 12月 19 2014 21:00:26 +08:00

连接到:
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing opt
ions

XFF_PDB@CHF> select * from v$version;

BANNER                                                 CON_ID
-------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.          0
1.0.2.0 - 64bit Production

PL/SQL Release 12.1.0.2.0 - Production                      0
CORE    12.1.0.2.0      Production                          0
TNS for 64-bit Windows: Version 12.1.0.2.0 - Produ          0
ction

NLSRTL Version 12.1.0.2.0 - Production                      0

XFF_PDB@CHF>  create table t_xifenfei (id number GENERATED ALWAYS AS IDENTITY,na
me varchar2(100));

表已创建。

XFF_PDB@CHF> select object_name,object_type from user_objects;

OBJECT_NAME     OBJECT_TYPE
--------------- -----------------------
ISEQ$$_91982    SEQUENCE
T_XIFENFEI      TABLE

XFF_PDB@CHF> set long 10000
XFF_PDB@CHF> select dbms_metadata.get_ddl('TABLE','T_XIFENFEI') FROM DUAL;

DBMS_METADATA.GET_DDL('TABLE','T_XIFENFEI')
--------------------------------------------------------------------------------
  CREATE TABLE "CHF"."T_XIFENFEI"
   (    "ID" NUMBER GENERATED ALWAYS AS IDENTITY MINVALUE 1 MAXVALUE
   9999999999999999999999999999 INCREMENT BY 1 START WITH 1 
   CACHE 20 NOORDER  NOCYCLE  NOT NULL ENABLE,
        "NAME" VARCHAR2(100)
   ) SEGMENT CREATION DEFERRED
  PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
 NOCOMPRESS LOGGING
  TABLESPACE "INMEMORY"

XFF_PDB@CHF> INSERT INTO T_XIFENFEI VALUES(1,'WWW.XIFNEFEI.COM');
INSERT INTO T_XIFENFEI VALUES(1,'WWW.XIFNEFEI.COM')
*
第 1 行出现错误:
ORA-32795: 无法插入到“始终生成”身份列


XFF_PDB@CHF> INSERT INTO T_XIFENFEI(name) VALUES('WWW.XIFNEFEI.COM');

已创建 1 行。

XFF_PDB@CHF> INSERT INTO T_XIFENFEI(name) VALUES('WWW.orasos.COM');

已创建 1 行。

XFF_PDB@CHF> commit;

提交完成。

XFF_PDB@CHF> col name for a30
XFF_PDB@CHF> select * from t_xifenfei;

        ID NAME
---------- ------------------------------
         1 WWW.XIFNEFEI.COM
         2 WWW.orasos.COM

XFF_PDB@CHF> update t_xifenfei set id=3 where id=2;
update t_xifenfei set id=3 where id=2
                      *
第 1 行出现错误:
ORA-32796: 无法更新“始终生成”身份列

XFF_PDB@CHF> delete from t_xifenfei where id=1;

已删除 1 行。

XFF_PDB@CHF> commit;

提交完成。

XFF_PDB@CHF> select ISEQ$$_91982.nextval from dual;

   NEXTVAL
----------
         3

XFF_PDB@CHF> INSERT INTO T_XIFENFEI(name) VALUES('WWW.ORASOS.COM');

已创建 1 行。

XFF_PDB@CHF> commit;

提交完成。

XFF_PDB@CHF> select * from t_xifenfei;

        ID NAME
---------- ------------------------------
         2 WWW.orasos.COM
         4 WWW.ORASOS.COM

XFF_PDB@CHF> ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 1
2';

会话已更改。

XFF_PDB@CHF>  select value from v$diag_info where name='Default Trace File';

VALUE
--------------------------------------------------------------------------------

D:\APP\FFCHENG\diag\rdbms\xff\xff\trace\xff_ora_10628.trc

XFF_PDB@CHF> INSERT INTO T_XIFENFEI(name) VALUES('WWW.XIFENFEI.COM');

已创建 1 行。

XFF_PDB@CHF> COMMIT;

提交完成。

--跟踪trace文件
PARSING IN CURSOR #688719640 len=55 dep=0 uid=103 oct=2 lid=103 tim=15129490112 hv=961646460 
ad='7ff05d11a18' sqlid='21uzyjhwp33vw'
INSERT INTO T_XIFENFEI(name) VALUES('WWW.XIFENFEI.COM')
END OF STMT
PARSE #688719640:c=15600,e=18909,p=0,cr=44,cu=0,mis=1,r=0,dep=0,og=1,plh=2541165129,tim=15129490112
EXEC #688719640:c=0,e=347,p=0,cr=1,cu=5,mis=0,r=1,dep=0,og=1,plh=2541165129,tim=15129490731
STAT #688719640 id=1 cnt=0 pid=0 pos=1 obj=0 op='LOAD TABLE CONVENTIONAL  T_XIFENFEI (cr=1 pr=0 pw=0 time=296 us)'
STAT #688719640 id=2 cnt=1 pid=1 pos=1 obj=91983 op='SEQUENCE  ISEQ$$_91982 (cr=0 pr=0 pw=0 time=89 us)'
WAIT #688719640: nam='SQL*Net message to client' ela= 2 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=15129490971

XFF_PDB@CHF> alter table t_xifenfei2 modify(id number GENERATED ALWAYS AS IDENTI
TY MINVALUE 1 MAXVALUE 99999999999999 INCREMENT BY 1 START WITH 1 CACHE  100);

表已更改。

XFF_PDB@CHF> drop sequence ISEQ$$_91982;
drop sequence ISEQ$$_91982
              *
第 1 行出现错误:
ORA-32794: 无法删除系统生成的序列

XFF_PDB@CHF> drop table t_xifenfei;

表已删除。

XFF_PDB@CHF> select object_name,object_type from user_objects where object_name=
'ISEQ$$_91982';

OBJECT_NAME          OBJECT_TYPE
-------------------- -----------------------
ISEQ$$_91982         SEQUENCE

XFF_PDB@CHF> select object_name,object_type from user_objects where object_name=
'ISEQ$$_91982';

OBJECT_NAME          OBJECT_TYPE
-------------------- -----------------------
ISEQ$$_91982         SEQUENCE

XFF_PDB@CHF> purge table t_xifenfei;

表已清除。

XFF_PDB@CHF> select object_name,object_type from user_objects where object_name=
'ISEQ$$_91982';

未选定行

这里的出来几个结论:
1. GENERATED ALWAYS AS IDENTITY 列无法人工指定值和修改该值
2. GENERATED IDENTITY 本质也是通过sequence实现
3. GENERATED IDENTITY 中sequence不能单独被删除
4. GENERATED IDENTITY 中的表删除,如果存在回收站中,该sequence依然存储,如果表被彻底删除,则sequence也被删除
5. GENERATED IDENTITY 中的sequence可以通过select 语句查询
6. 通过alert table 语句来修改GENERATED IDENTITY 的sequence相关值

GENERATED BY DEFAULT AS IDENTITY方式测试

XFF_PDB@CHF>  create table t_xifenfei2 (id number GENERATED BY DEFAULT AS IDENTI
TY,name varchar2(100)) tablespace users;

表已创建。

XFF_PDB@CHF> insert into t_xifenfei2 values (1,'www.xifenfei.com');

已创建 1 行。

XFF_PDB@CHF> insert into t_xifenfei2(name) values ('www.orasos.com');

已创建 1 行。

XFF_PDB@CHF> col name for a20
XFF_PDB@CHF> select * from t_xifenfei2;

        ID NAME
---------- --------------------
         1 www.xifenfei.com
         1 www.orasos.com

XFF_PDB@CHF> insert into t_xifenfei2 values (null,'www.xifenfei.com');
insert into t_xifenfei2 values (null,'www.xifenfei.com')
                                *
第 1 行出现错误:
ORA-01400: 无法将 NULL 插入 ("CHF"."T_XIFENFEI2"."ID")


XFF_PDB@CHF> desc t_xifenfei2
 名称                                      是否为空? 类型
 ----------------------------------------- -------- ---------------------------

 ID                                        NOT NULL NUMBER
 NAME                                               VARCHAR2(100)

得出结论:
1. GENERATED BY DEFAULT AS IDENTITY方式不能在该列中插入null值
2. GENERATED BY DEFAULT AS IDENTITY方式可以指定具体值插入

GENERATED BY DEFAULT ON NULL AS IDENTITY方式测试

XFF_PDB@CHF>  create table t_xifenfei3 (id number GENERATED BY DEFAULT on null A
S IDENTITY,name varchar2(100)) tablespace users;

表已创建。

XFF_PDB@CHF> desc t_xifenfei3
 名称                                      是否为空? 类型
 ----------------------------------------- -------- ----------------------------

 ID                                        NOT NULL NUMBER
 NAME                                               VARCHAR2(100)

XFF_PDB@CHF> insert into t_xifenfei3 values (null,'www.xifenfei.com');

已创建 1 行。

XFF_PDB@CHF> select * from t_xifenfei3;

        ID NAME
---------- --------------------
         1 www.xifenfei.com

测试结论:GENERATED BY DEFAULT ON NULL AS IDENTITY的列上可以查询null值,只是默认转换为对应的sequence值

传统自增长列实现方法

XFF_PDB@CHF> create table t_xifenfei4 (id number,name varchar2(100)) tablespace
users;

表已创建。

XFF_PDB@CHF> create sequence xff_sequence
  2  increment by 1
  3  minvalue 1
  4  nomaxvalue
  5  start with 1
  6  cache 20
  7  order;

序列已创建。

XFF_PDB@CHF> create or replace trigger xifenfei_id
  2  before insert on t_xifenfei4
  3  for each row
  4  begin
  5  select xff_sequence.nextval into :new.id from dual;
  6  end;
  7  /

触发器已创建

XFF_PDB@CHF> insert into t_xifenfei4(name) values('www.xifenfei.com');

已创建 1 行。

XFF_PDB@CHF> select * from t_xifenfei4;

        ID NAME
---------- --------------------
         1 www.xifenfei.com
发表在 ORACLE 12C | 标签为 , | 评论关闭