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

Home -> Community -> Mailing Lists -> Oracle-L -> RE: From row to datafile

RE: From row to datafile

From: Riyaj Shamsudeen <rshamsud_at_jcpenney.com>
Date: Wed, 04 Aug 2004 17:13:35 -0500
Message-id: <004901c47a70$4917f850$212f200a@rshamsudxp>


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_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org] On Behalf Of DENNIS WILLIAMS Sent: Wednesday, August 04, 2004 4:01 PM To: 'oracle-l_at_freelists.org'
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_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
-----------------------------------------------------------------



-- 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_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 Wed Aug 04 2004 - 17:09:29 CDT

Original text of this message

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