RE: From row to datafile

  • From: DENNIS WILLIAMS <DWILLIAMS@xxxxxxxxxxxxx>
  • To: "'oracle-l@xxxxxxxxxxxxx'" <oracle-l@xxxxxxxxxxxxx>
  • Date: Thu, 5 Aug 2004 15:50:34 -0500

Thanks everyone, especially Riyaj and Ian. I really appreciate the hard
work.

Riyaj
   I tried to follow your method and seemed to be successful until I got
down to the last step. I found the block and record of the main table. I
dumped the block of the main table and got the following for the 35th record
in the trace file:

tab 0, row 35, @0x3219
tl: 96 fb: --H-FL-- lb: 0x0  cc: 9
col  0: [ 4]  c3 4b 5c 0b
col  1: [ 4]  6b 65 79 31
col  2: [32]
 64 38 37 66 33 36 61 30 64 66 32 33 31 38 37 31 35 61 39 65 38 66 34 62 35
 37 65 62 35 62 37 32
col  3: [ 3]  4d 44 35
col  4: [ 3]  c2 04 19
col  5: [ 3]  c2 03 35
col  6: [20]  00 54 00 01 01 08 00 00 00 01 00 00 00 01 00 00 00 0c 08 3b
col  7: [ 7]  78 68 08 05 0c 1e 33
col  8: [ 8]  55 50 44 5f 55 53 45 52
tab 0, row 36, @0x31b9

However, when I convert c083b to decimal I get 788539. I plug that into your
SQL query for the dba and recieve for file number . . . . 0! Can you spot
where I've gotten off the path? Again, thanks for all your help.

Dennis Williams
DBA
Lifetouch, Inc.

"We all want progress, but if you're on the wrong road, progress means
doing an about-turn and walking back to the right road; in that case,
the man who turns back soonest is the most progressive." 
-- C.S. Lewis


-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx]On Behalf Of Riyaj Shamsudeen
Sent: Wednesday, August 04, 2004 5:14 PM
To: oracle-l@xxxxxxxxxxxxx
Subject: RE: From row to datafile


Dennis
        I am afraid, there is no straight forward way to find the blobs
and their file location (at least not that I know of). But you could
dump the blocks as in the following example to find the file, blob is
located:
1. Find the file id block id from the table:
Select  dbms_rowid.rowid_relative_fno
(rowid)||','||dbms_rowid.rowid_block_number (rowid)||','
||Dbms_rowid.rowid_row_number(rowid) File_block_row
From your_table 
Where your_where_condition
/

43,651713,1

2. Dump the block:
Using the file and block dump the block..

Alter system dump datafile <fileid> block min <blockid> block max
<blockid>

Alter system dump datafile 43 block min 651713 block max 651713

3. Look at the trace file and look for the row number from the query 1,
in the dump..

tab 0, row 1, @0x178e
tl: 46 fb: --H-FL-- lb: 0x1 cc: 2

4. For the lob columns stored out of line: dba is in the last four
bytes.. Here is an example..Second columns I blob for me. Count starts
from 0.

col  1: [40]
 00 54 00 01 02 0c 00 00 00 01 00 00 00 01 00 00 04 0e f8 c3 00 14 05 00
00
 00 00 00 0f a0 00 00 00 00 00 02 0a c9 f2 5e

        Here 0ac9f25e is the dba of the out of line lob.

5. Convert this to decimal 181006942.

6. Find the file and block using the above dba.. 
undef dba
select
dbms_utility.DATA_BLOCK_ADDRESS_FILE(&&dba)||','||
dbms_utility.DATA_BLOCK_ADDRESS_BLOCK(&&dba)
from dual
/

7. You can also dump this lob block to confirm that this analysis is
correct..

buffer tsn: 21 rdba: 0x0ac9f25e (43/651870)
scn: 0x0518.8462f4a6 seq: 0x02 flg: 0x00 tail: 0xf4a61b02
frmt: 0x02 chkval: 0x0000 type: 0x1b=LOB BLOCK

Long field block dump:
Object Id   297174
LobId: 0001004EF8C3 PageNo        0
Version: 0x0000.00000001

PS: This is 8i, 64 bit on Solaris.. 

HTH

Thanks
Riyaj "Re-yas" Shamsudeen
Certified Oracle DBA


-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of DENNIS WILLIAMS
Sent: Wednesday, August 04, 2004 4:01 PM
To: 'oracle-l@xxxxxxxxxxxxx'
Subject: From row to datafile


List - Does anyone know how to relate a database row to the datafile
where it is stored? Here is the situation: we are going to test the
recovery of a database, removing a few data files and then recovering
them from RMAN backup. These data files store image blobs out-of-line. I
would like to be able to list a few images from a particular data file
so after recovery we could retrieve those images. There are some queries
for dealing with database corruption where you can take a given file and
block and relate it back using dba_segments and sys.uet$. I'm not sure
how to work for a specific row or with out-of-line blobs. Any ideas
appreciated.


Dennis Williams
DBA
Lifetouch, Inc.

"We all want progress, but if you're on the wrong road, progress means
doing an about-turn and walking back to the right road; in that case,
the man who turns back soonest is the most progressive." 
-- C.S. Lewis

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx put
'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------



-- Attached file included as plaintext by Ecartis --
-- Desc: Signature

The information transmitted is intended only for the person or entity to
which it is addressed and may contain confidential and/or privileged
material.  If the reader of this message is not the intended recipient,
you are hereby notified that your access is unauthorized, and any review,
dissemination, distribution or copying of this message including any
attachments is strictly prohibited.   If you are not the intended
recipient, please contact the sender and delete the material from any
computer.


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: