Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> research the DB open

research the DB open

From: biti_rainy <biti_rainy_at_itpub.net>
Date: 22 Apr 2004 13:55:50 -0000
Message-Id: <20040422134020.D46DC72CEB5@turing.freelists.org>


hi
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount
ORACLE instance started.
Total System Global Area 131142648 bytes Fixed Size 451576 bytes
Variable Size 104857600 bytes
Database Buffers 25165824 bytes
Redo Buffers 667648 bytes
Database mounted.
SQL> alter session set sql_trace = true;

Session altered.

SQL> alter database open;

Database altered.

SQL> (reference to the trace file )

>#1st

create table bootstrap$ ( line# number not null, obj# number not null, sql_text varchar2(4000) not null) storage (initial 50K objno 56 extents (file 1 block 377))

>#2nd

select line#, sql_text
from
bootstrap$ where obj# != :1 --- the var should be -1

>#let's look at the bootstrap$

SQL> desc bootstrap$
Name Null? Type

----------------------------------------- -------- ----------------------------
LINE# NOT NULL NUMBER
OBJ# NOT NULL NUMBER
SQL_TEXT NOT NULL VARCHAR2(4000) SQL> SQL> select count(*) from bootstrap$;
57

SQL> SQL> select obj#,sql_text from bootstrap$ where rownum<11; -1
8.0.0.0.0

0
CREATE ROLLBACK SEGMENT SYSTEM STORAGE ( INITIAL 112K NEXT 1024K MINEXTENTS 1 M AXEXTENTS 32765 OBJNO 0 EXTENTS (FILE 1 BLOCK 9)) 8
CREATE CLUSTER C_FILE#_BLOCK#("TS#" NUMBER,"SEGFILE#" NUMBER,"SEGBLOCK#" NUMBER) PCTFREE 10 PCTUSED 40 INITRANS 2 MAXTRANS 255 STORAGE ( INITIAL 24K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJNO 8 EXTENTS (FILE 1 BLOCK 73)) SIZE 225 9
CREATE INDEX I_FILE#_BLOCK# ON CLUSTER C_FILE#_BLOCK# PCTFREE 10 INITRANS 2 MAXT RANS 255 STORAGE ( INITIAL 64K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PC TINCREASE 0 OBJNO 9 EXTENTS (FILE 1 BLOCK 81)) 14
CREATE TABLE SEG$("FILE#" NUMBER NOT NULL,"BLOCK#" NUMBER NOT NULL,"TYPE#" NUMBE R NOT NULL,"TS#" NUMBER NOT NULL,"BLOCKS" NUMBER NOT NULL,"EXTENTS" NUMBER NOT N ULL,"INIEXTS" NUMBER NOT NULL,"MINEXTS" NUMBER NOT NULL,"MAXEXTS" NUMBER NOT NUL L,"EXTSIZE" NUMBER NOT NULL,"EXTPCT" NUMBER NOT NULL,"USER#" NUMBER NOT NULL,"LI STS" NUMBER,"GROUPS" NUMBER,"BITMAPRANGES" NUMBER NOT NULL,"CACHEHINT" NUMBER NO T NULL,"SCANHINT" NUMBER NOT NULL,"HWMINCR" NUMBER NOT NULL,"SPARE1" NUMBER,"SPA RE2" NUMBER) STORAGE ( OBJNO 14 TABNO 2) CLUSTER C_FILE#_BLOCK#(TS#,FILE#,BLOCK #)

5
CREATE TABLE CLU$("OBJ#" NUMBER NOT NULL,"DATAOBJ#" NUMBER,"TS#" NUMBER NOT NULL ,"FILE#" NUMBER NOT NULL,"BLOCK#" NUMBER NOT NULL,"COLS" NUMBER NOT NULL,"PCTFRE E$" NUMBER NOT NULL,"PCTUSED$" NUMBER NOT NULL,"INITRANS" NUMBER NOT NULL,"MAXTR

ANS" NUMBER NOT NULL,"SIZE$" NUMBER,"HASHFUNC" VARCHAR2(30),"HASHKEYS" NUMBER,"F
UNC" NUMBER,"EXTIND" NUMBER,"FLAGS" NUMBER,"DEGREE" NUMBER,"INSTANCES" NUMBER,"A
VGCHN" NUMBER,"SPARE1" NUMBER,"SPARE2" NUMBER,"SPARE3" NUMBER,"SPARE4" NUMBER,"S
PARE5" VARCHAR2(1000),"SPARE6" VARCHAR2(1000),"SPARE7" DATE) STORAGE ( OBJNO 5 TABNO 2) CLUSTER C_OBJ#(OBJ#) 6
CREATE CLUSTER C_TS#("TS#" NUMBER) PCTFREE 10 PCTUSED 40 INITRANS 2 MAXTRANS 255 STORAGE ( INITIAL 64K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREAS E 0 OBJNO 6 EXTENTS (FILE 1 BLOCK 57)) 7
CREATE INDEX I_TS# ON CLUSTER C_TS# PCTFREE 10 INITRANS 2 MAXTRANS 255 STORAGE ( INITIAL 64K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJNO 7 EXTENTS (FILE 1 BLOCK 65)) 18
CREATE TABLE OBJ$("OBJ#" NUMBER NOT NULL,"DATAOBJ#" NUMBER,"OWNER#" NUMBER NOT N ULL,"NAME" VARCHAR2(30) NOT NULL,"NAMESPACE" NUMBER NOT NULL,"SUBNAME" VARCHAR2( 30),"TYPE#" NUMBER NOT NULL,"CTIME" DATE NOT NULL,"MTIME" DATE NOT NULL,"STIME" DATE NOT NULL,"STATUS" NUMBER NOT NULL,"REMOTEOWNER" VARCHAR2(30),"LINKNAME" VAR CHAR2(128),"FLAGS" NUMBER,"OID$" RAW(16),"SPARE1" NUMBER,"SPARE2" NUMBER,"SPARE3 " NUMBER,"SPARE4" VARCHAR2(1000),"SPARE5" VARCHAR2(1000),"SPARE6" DATE) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 STORAGE ( INITIAL 16K NEXT 1024K MINEXTEN TS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJNO 18 EXTENTS (FILE 1 BLOCK 121)) 36
CREATE UNIQUE INDEX I_OBJ1 ON OBJ$(OBJ#) PCTFREE 10 INITRANS 2 MAXTRANS 255 STOR AGE ( INITIAL 64K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 O BJNO 36 EXTENTS (FILE 1 BLOCK 217)) 10 rows selected.

SQL>
>#we can see that the bootstrap$ stored the DDL script for the system objects
>#let's check the trace content

CREATE ROLLBACK SEGMENT SYSTEM STORAGE ( INITIAL 112K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 32765 OBJNO 0 EXTENTS (FILE 1 BLOCK 9))
>#here create a system rollback segment header at "file 1 block 9"(LMT ,not DMT)
>#go on

CREATE CLUSTER C_OBJ#("OBJ#" NUMBER) PCTFREE 5 PCTUSED 40 INITRANS 2 MAXTRANS 255 STORAGE ( INITIAL 136K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJNO 2 EXTENTS (FILE 1 BLOCK 25)) SIZE 800
># notice that "OBJNO 2 EXTENTS (FILE 1 BLOCK 25)) SIZE 800"
>#query

SQL> select file_id,block_id from dba_extents where segment_name = 'C_OBJ#'; 1 25
1 33
1 41
1 3241
1 4441
1 4473
1 4489
1 4513
1 4529
1 4561
1 4585
1 4609
1 4641
1 4681
1 4753
1 4833
1 4873
1 12681
1 23689
1 26249

20 rows selected.

>#go on

CREATE INDEX I_OBJ# ON CLUSTER C_OBJ# PCTFREE 10 INITRANS 2 MAXTRANS 255 STORAGE ( INITIAL 64K NEXT 1024K MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 OBJNO 3 EXTENTS (FILE 1 BLOCK 49)) CREATE TABLE TAB$("OBJ#" NUMBER NOT NULL,"DATAOBJ#" NUMBER,"TS#" NUMBER NOT NULL,"FILE#" NUMBER NOT NULL,"BLOCK#" NUMBER NOT NULL,"BOBJ#" NUMBER,"TAB#" NUMBER,"COLS" NUMBER NOT NULL,"CLUCOLS" NUMBER,"PCTFREE$" NUMBER NOT NULL, "PCTUSED$" NUMBER NOT NULL,"INITRANS" NUMBER NOT NULL,"MAXTRANS" NUMBER NOT NULL,"FLAGS" NUMBER NOT NULL,"AUDIT$" VARCHAR2(38) NOT NULL,"ROWCNT" NUMBER,

"BLKCNT" NUMBER,"EMPCNT" NUMBER,"AVGSPC" NUMBER,"CHNCNT" NUMBER,"AVGRLN" 
NUMBER,"AVGSPC_FLB" NUMBER,"FLBCNT" NUMBER,"ANALYZETIME" DATE,"SAMPLESIZE" 
NUMBER,"DEGREE" NUMBER,"INSTANCES" NUMBER,"INTCOLS" NUMBER NOT NULL,
"KERNELCOLS" NUMBER NOT NULL,"PROPERTY" NUMBER NOT NULL,"TRIGFLAG" NUMBER,
"SPARE1" NUMBER,"SPARE2" NUMBER,"SPARE3" NUMBER,"SPARE4" VARCHAR2(1000), "SPARE5" VARCHAR2(1000),"SPARE6" DATE) STORAGE ( OBJNO 4 TABNO 1) CLUSTER C_OBJ#(OBJ#)
># from tab$ , notice that "STORAGE ( OBJNO 4 TABNO 1) CLUSTER C_OBJ#(OBJ#)"
># what are the "objno 4 tabno 1" ? we can look up the tab$ via "cluster C_OBJ#(OBJ#)"

SQL> select * from tab$ where obj# = 4 and tab# = 1;

OBJ# DATAOBJ# TS# FILE# BLOCK# BOBJ# TAB# ---------- ---------- ---------- ---------- ---------- ---------- ---------- COLS CLUCOLS PCTFREE$ PCTUSED$ INITRANS MAXTRANS FLAGS ---------- ---------- ---------- ---------- ---------- ---------- ---------- AUDIT$ ROWCNT BLKCNT EMPCNT

-------------------------------------- ---------- ---------- ----------
AVGSPC CHNCNT AVGRLN AVGSPC_FLB FLBCNT ANALYZETI SAMPLESIZE ---------- ---------- ---------- ---------- ---------- --------- ---------- DEGREE INSTANCES INTCOLS KERNELCOLS PROPERTY TRIGFLAG SPARE1 ---------- ---------- ---------- ---------- ---------- ---------- ---------- SPARE2 SPARE3
---------- ----------
SPARE4

SPARE5

SPARE6

4 2 0 1 25 2 1
37 1 0 0 0 0 17
-------------------------------- 921 428 83
2381 0 139 6368 7 11-AUG-03 921
37 37 1024 0 0

06-AUG-03 SQL>  
># now we see that from here to DB complete open, all the objects storage come from fixed file# and block#
># so if these system block corrupted ,the DB can not open

  one year ago , i thought that oracle can query much information via the data dictionary tables/views but , how to found the basic information . the data are stored in system but we can query it on sql . user table's structure information come from DICT tables , but how about the DICT table's structure information ?

 so i do the test ,and find the egg ---- bootstrap$ the egg can hatch the c_obj$ and tab$ ...

i guess the bootstrap$'s structure or storage information are also stored in the oracle code (like oracle.exe) and when opening , oracle only create the structrue(include the storage information) in the shared pool but do not create the segment in the system tablespace . and , the "DDL" do not live in the shared pool,we can not query it in v$sql/v$sqlarea .   

Best regards

yahoo id: feng_chunpei
A new dba from china


Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Thu Apr 22 2004 - 08:50:52 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US