联系:手机/微信(+86 17813235971) QQ(107644445)
作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]
对数据库有一定了解的人都知道,数据库启动是通过bootstarp$表来实现启动引导的。那这里有两个疑问:
1.引导表bootstarp$名字是否是唯一?
2.引导表的位置是不是在数据文件固定?比如11g/12c在file 1 block 520,10g在file 1 block 377?
跟踪数据库启动
[oracle@rac2 ~]$ sqlplus / as sysdba SQL*Plus: Release 12.1.0.1.0 Production on Sun Dec 15 14:16:58 2013 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production With the Partitioning, Real Application Clusters, OLAP, Advanced Analytics and Real Application Testing options SQL> startup mount; ORACLE instance started. Total System Global Area 400846848 bytes Fixed Size 2288872 bytes Variable Size 310379288 bytes Database Buffers 79691776 bytes Redo Buffers 8486912 bytes Database mounted. SQL> oradebug setmypid Statement processed. SQL> alter session set db_file_multiblocK_read_count=1; Statement processed. SQL> oradebug EVENT 10046 TRACE NAME CONTEXT FOREVER, LEVEL 12 Session altered. SQL> oradebug TRACEFILE_NAME /u01/app/oracle/diag/rdbms/test/TEST/trace/TEST_ora_31364.trc SQL> alter database Open; Database altered. SQL> oradebug EVENT 10046 trace name context off Statement processed. SQL> select HEADER_FILE,HEADER_BLOCK from dba_segments where segment_name='BOOTSTRAP$'; HEADER_FILE HEADER_BLOCK ----------- ------------ 1 520 SQL> select object_id from dba_objects where object_name='BOOTSTRAP$'; OBJECT_ID ---------- 59
分析trace文件
WAIT #140077386411120: nam='db file sequential read' ela= 56 file#=1 block#=520 blocks=1 obj#=-1 tim=1719385755334 ===================== PARSING IN CURSOR #140077386402760 len=188 dep=1 uid=0 oct=1 lid=0 tim=1719385757322 hv=4006182593 ad='6645d370' sqlid='32r4f1brckzq1' create table bootstrap$ ( END OF STMT PARSE #140077386402760:c=2000,e=1711,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=0,tim=1719385757319 EXEC #140077386402760:c=0,e=430,p=0,cr=0,cu=0,mis=0,r=0,dep=1,og=4,plh=0,tim=1719385757909 CLOSE #140077386402760:c=0,e=9,dep=1,type=0,tim=1719385758105 ===================== PARSING IN CURSOR #140077386402760 len=55 dep=1 uid=0 oct=3 lid=0 tim=1719385759507 hv=2111436465 ad='6645bc80' sqlid='6apq2rjyxmxpj' select line#, sql_text from bootstrap$ where obj# != :1 END OF STMT PARSE #140077386402760:c=1000,e=1365,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=0,tim=1719385759505 BINDS #140077386402760: Bind#0 oacdty=02 mxl=22(22) mxlc=00 mal=00 scl=00 pre=00 oacflg=08 fl2=1000001 frm=00 csi=00 siz=24 off=0 kxsbbbfp=7f664edb8780 bln=22 avl=02 flg=05 value=59 EXEC #140077386402760:c=3000,e=8859,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=867914364,tim=1719385768574 WAIT #140077386402760: nam='db file sequential read' ela= 27 file#=1 block#=520 blocks=1 obj#=59 tim=1719385768753 WAIT #140077386402760: nam='db file sequential read' ela= 23 file#=1 block#=521 blocks=1 obj#=59 tim=1719385769575
这里我们可以发现,数据库启动的时候是读file 1 block 520,object_id为59,为bootstarp$对象
bbed查看root rdba地址
ub4 kcvfhrdb @96 0x00400208 SQL> select to_number('208','xxx') from dual; TO_NUMBER('208','XXX') ---------------------- 520
这里可以看出来,数据库启动的file header rdba地址和trace文件中的一致,也是指定到bootstarp$;
替换bootstrap$表为xifenfei
SQL> create table xifenfei as select * from bootstrap$; Table created. SQL> desc xifenfei Name Null? Type ----------------------------------------- -------- ---------------------------- LINE# NOT NULL NUMBER OBJ# NOT NULL NUMBER SQL_TEXT NOT NULL VARCHAR2(4000) SQL> select sql_text from xifenfei where line#=59; SQL_TEXT -------------------------------------------------------------------------------- CREATE TABLE BOOTSTRAP$("LINE#" NUMBER NOT NULL,"OBJ#" NUMBER NOT NULL,"SQL_TEXT " VARCHAR2(4000) NOT NULL) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 STORAGE ( INITIAL 56K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJN O 59 EXTENTS (FILE 1 BLOCK 520)) --清除bootstarp$记录 SQL> delete from xifenfei where line#=59; 1 row deleted. SQL> commit; Commit complete. SQL> select objECT_ID from dba_objects where object_name='XIFENFEI'; OBJECT_ID ---------- 20314 SQL> select HEADER_FILE,HEADER_BLOCK from dba_segments where segment_name='XIFENFEI'; HEADER_FILE HEADER_BLOCK ----------- ------------ 1 45712 SQL> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. SQL> startup upgrade; ORACLE instance started. Total System Global Area 400846848 bytes Fixed Size 2288872 bytes Variable Size 310379288 bytes Database Buffers 79691776 bytes Redo Buffers 8486912 bytes Database mounted. Database opened. --删除bootstarp$表 SQL> drop table bootstrap$; Table dropped. SQL> exec DBMS_DDL_INTERNAL.SWAP_BOOTSTRAP('XIFENFEI'); PL/SQL procedure successfully completed. SQL> shutdown immediate; Database closed. Database dismounted. ORACLE instance shut down. SQL> EXIT Disconnected from Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production With the Partitioning, Real Application Clusters, OLAP, Advanced Analytics and Real Application Testing options [oracle@rac2 ~]$ sqlplus / as sysdba SQL*Plus: Release 12.1.0.1.0 Production on Sun Dec 15 14:29:54 2013 Copyright (c) 1982, 2013, Oracle. All rights reserved. Connected to an idle instance. SQL> STARTUP MOUNT ORACLE instance started. Total System Global Area 400846848 bytes Fixed Size 2288872 bytes Variable Size 310379288 bytes Database Buffers 79691776 bytes Redo Buffers 8486912 bytes Database mounted. SQL> oradebug setmypid Statement processed. SQL> oradebug EVENT 10046 TRACE NAME CONTEXT FOREVER, LEVEL 12 Statement processed. SQL> alter session set db_file_multiblocK_read_count=1; Session altered. SQL> oradebug TRACEFILE_NAME /u01/app/oracle/diag/rdbms/test/TEST/trace/TEST_ora_32727.trc SQL> alter database Open; Database altered. SQL> SELECT OBJECT_ID FROM DBA_OBJECTS WHERE OBJECT_NAME='BOOTSTRAP$'; no rows selected SQL> SELECT OBJECT_ID FROM DBA_OBJECTS WHERE OBJECT_NAME='XIFENFEI'; OBJECT_ID ---------- 20314
分析trace文件
WAIT #139841534602352: nam='db file sequential read' ela= 23 file#=1 block#=45712 blocks=1 obj#=-1 tim=1720082484775 ===================== PARSING IN CURSOR #139841534593992 len=193 dep=1 uid=0 oct=1 lid=0 tim=1720082488552 hv=2096904950 ad='6645d650' sqlid='bs6v55xygsfrq' create table bootstrap$ ( END OF STMT PARSE #139841534593992:c=2000,e=2925,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=0,tim=1720082488550 EXEC #139841534593992:c=0,e=466,p=0,cr=0,cu=0,mis=0,r=0,dep=1,og=4,plh=0,tim=1720082489124 CLOSE #139841534593992:c=0,e=8,dep=1,type=0,tim=1720082489266 ===================== PARSING IN CURSOR #139841534593992 len=55 dep=1 uid=0 oct=3 lid=0 tim=1720082490510 hv=2111436465 ad='6645c050' sqlid='6apq2rjyxmxpj' select line#, sql_text from bootstrap$ where obj# != :1 END OF STMT PARSE #139841534593992:c=1999,e=1211,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=0,tim=1720082490509 BINDS #139841534593992: Bind#0 oacdty=02 mxl=22(22) mxlc=00 mal=00 scl=00 pre=00 oacflg=08 fl2=1000001 frm=00 csi=00 siz=24 off=0 kxsbbbfp=7f2f64fe8780 bln=22 avl=04 flg=05 value=20314 EXEC #139841534593992:c=1000,e=1789,p=0,cr=0,cu=0,mis=1,r=0,dep=1,og=4,plh=867914364,tim=1720082492533 WAIT #139841534593992: nam='db file sequential read' ela= 20 file#=1 block#=45712 blocks=1 obj#=20314 tim=1720082492685 WAIT #139841534593992: nam='db file sequential read' ela= 25 file#=1 block#=45713 blocks=1 obj#=20314 tim=1720082492986
这里可以看出来,数据库在启动的时候是读取file 1 block 45712,object_id为20314
bbed查看root rdba地址
ub4 kcvfhrdb @96 0x0040b290 SQL> select to_number('b290','xxxxxxx') from dual; TO_NUMBER('B290','XXXXXXX') --------------------------- 45712
证明现在的文件头里面的file header rdba 已经修改为file 1 block 45712和trace里面看到的一致,都是XIFENFEI这个表
测试结论
1. 通过使用SWAP_BOOTSTRAP可以置换掉数据库启动开始表bootstrap$变为另外一个表,而且该过程直接修改文件头的kcvfhrdb值
2. 通过试验证明,oracle启动的时候不是程序里面写死的去读file 1的某个block,而是通过读取kcvfhrdb然后启动数据库
非默认的bootstarp$表位置,dul依然能够识别,证明dul是根据kcvfhrdb来寻找bootstarp$表
问一个问题,同一版本下 bootstrap$ 表内容是不是一样的?换句话说该bootstrap$ 有问题,是否可以用其他的库的bootstrap$ 替换,通过dd 命令拷贝复制到有问题的bootstrap$里?