But why do you need to take a pain of this kind just for 
checking the total no of rows in individual blocks......

Just run following SQLs and find better idea of space usage
inside the blocks.......

REM Remember ......the Rowid format is 
REM oooooofffbbbbbbrrr
REM 
REM FOLLOWING QUERY IS TO DETERMINE TOTAL NO OF USED BLOCKS
REM FOR A GIVEN TABLE THAT HAVE AT LEAST ONE ROW IN THEM
REM
REM
prompt ENTER TABLE NAME AS OWNER.TABLE

SELECT COUNT(DISTINCT SUBSTR(ROWID,1,15)) FROM &&TABLE 
/

REM FOLLOWING QUERY IS TO DETERMINE MAX NO OF ROWS
REM AMONG ALL THE DATABLOCKS FOR A GIVEN TABLE

SELECT MAX(COUNT(*)) FROM &&TABLE
GROUP BY SUBSTR(ROWID,1,15)
/
REM FOLLOWING QUERY IS TO DETERMINE MIN NO OF ROWS
REM AMONG ALL THE DATABLOCKS FOR A GIVEN TABLE

SELECT MIN(COUNT(*)) FROM &&TABLE
GROUP BY SUBSTR(ROWID,1,15)
/

REM FOLLOWING QUERY IS TO DETERMINE AVG NO OF ROWS
REM AMONG ALL THE DATABLOCKS FOR A GIVEN TABLE

SELECT AVG(COUNT(*)) FROM &&TABLE
GROUP BY SUBSTR(ROWID,1,15)
/

REM FOLLOWING QUERY IS TO DETERMINE BLOCK IDs WHO HAVE
REM SPECIFIC ROWCOUNT ....
REM Check Only last 6 characters for Block ids..

SELECT DISTINCT SUBSTR(ROWID,1,15) "OOOOOOFFFBBBBBB" , COUNT(*) FROM
&&TABLE 
GROUP BY SUBSTR(ROWID,1,15) HAVING COUNT(*) = &ROWCOUNT
/

REM FOLLOWING QUERY IS TO GIVE COUNT OF ROWS IN ALL 
REM BLOCKS INDIVIDUALLY.....
REM
REM THIS WILL OUTPUT AS MANY ROWS AS TOTAL NO OF USED 
REM BLOCKS IN THE TABLE.......

SELECT SUBSTR(ROWID,1,15) "OOOOOOFFFBBBBBB", COUNT(*) FROM &&TABLE
GROUP BY SUBSTR(ROWID,1,15) ORDER BY COUNT(*) 
/

REM THIS IS EXCELLENT EXMAPLE OF ONLINE REMOVAL OF
REM DATA BLOCK FRAGMENTATION.....
REM 
REM FOLLOWING SQL IS TO CREATE A TEMP TABLE WHICH WILL HAVE
REM ALL THE ROWS OF THE BLOCKS, WHO HAVE A SPECIFIC ROWCOUNT.
REM AFTER CREATING THIS TEMP TABLE, ONE CAN DELETE THE ROWS
REM FROM MAIN TABLE AND REINSERT THE ROWS FROM TEMP TABLE.
REM THIS WILL ELIMINATE THE DATA BLOCK FRAGMENTATION FOR ALL
REM THE BLOCKS HAVING ROWCOUNT SPECIFIED....
REM
REM HERE BEFORE REINSERTION INTO MAIN TABLE PCTFREE VALUE CAN
REM BE SET TO A VERY LOW VALUE (2-5%).....
REM
REM AFTER REINSERTION IS COMPLETE, THE PCTFREE CAN BE RESET TO 
REM ORIGINAL VALUE.......
REM 
REM THIS OPERATION CAN BE VERIFIED BY RECHECKING THE NO OF ROWS
REM FOR THESE BLOCKS....
REM
REM 
REM  ALERT!!!!!!!DON'T FORGET ABOUT TRIGGERS AND CONSTRAINTS .........
REM
REM
REM  CREATE TABLE TEMP11 AS SELECT * FROM &&TABLE
REM  WHERE SUBSTR(ROWID,10,6) IN (
REM  SELECT DISTINCT SUBSTR(ROWID,10,6) FROM &&TABLE
REM  GROUP BY SUBSTR(ROWID,10,6) HAVING COUNT(*) = &ROWCOUNT
REM  )
REM  /

UNDEFINE TABLE

NOTE: Would wait for the feedback.

Hope this helps a bit,
Rajesh

-----Original Message-----
bhatti
Sent: Wednesday, September 26, 2001 1:30 AM
To: Multiple recipients of list ORACLE-L


Aha, you're right.  I do indeed notice a value,
nrow=87.  

Thank you

mkb

--- K Gopalakrishnan <[EMAIL PROTECTED]> wrote:
> 
> Hi,
> 
> You don't need to do arithmetic to find number of
> rows in a block from block dumps. There will be a
> component in block dump called 'numrow' or 'nrow'
> which will tell how many rows are there in that
> block.
> 
> It will be something like that in case if you have
> 20 rows
> 
> nrow=20
> 
> Best Regards,
> K Gopalakrishnan
> Bangalore, INDIA
> 
> 
> -----Original Message-----
> bhatti
> Sent: Tuesday, September 25, 2001 11:41 AM
> To: Multiple recipients of list ORACLE-L
> 
> 
> OK, so somebody asks me if there is a way to
> determine
> how full an Oracle data block is.  I've been playing
> around with dbms_space and dbms_rowid packages but
> apparently, I can't see how these would help.  A
> couple interesting scripts both on ixora and
> Jonathan
> Lewis web site seem to have helped.  I used JL's
> script 'alter system dump datafile <df_no> block min
> <min_blk> block max <max_blk>;' to dump the segment
> header and block headers for various data blocks.
> 
> For example, if I run this:
> 
> alter system dump datafile 122 block min 4 block max
> 4, I dump the header info for block 4 in datafile
> 122.
> 
> Question is, when I look in the trace file I see the
> following line:
> block_row_dump
> tab 0, row 53, @0x46c
> tl: 2 fb: --HDFL-- lb:0x1
> ...
> ...
> tab 0, row 98, @0x1f21
> tl: 2 fb: --HDFL-- lb: 0x1
> end_of_block_dump
> 
> So, am I correct in assuming that there are 46 rows
> (98-53+1=46) in this block?  If this is the case, I
> would be able to calculate the average row size for
> this block and do all sorts of silly little
> 'rithmetic
> calculations based on pctfree etc.  This would give
> fairly granular insight into how tightly packed
> blocks
> are, right?
> 
> Any opinions?
> 
> tia
> 
> mkb
> 
> 
> __________________________________________________
> Do You Yahoo!?
> Get email alerts & NEW webcam video instant
> messaging with Yahoo! Messenger.
> http://im.yahoo.com
> --
> Please see the official ORACLE-L FAQ:
> http://www.orafaq.com
> --
> Author: mohammed bhatti
>   INET: [EMAIL PROTECTED]
> 
> Fat City Network Services    -- (858) 538-5051  FAX:
> (858) 538-5051
> San Diego, California        -- Public Internet
> access / Mailing Lists
>
--------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an
> E-Mail message
> to: [EMAIL PROTECTED] (note EXACT spelling of
> 'ListGuru') and in
> the message BODY, include a line containing: UNSUB
> ORACLE-L
> (or the name of mailing list you want to be removed
> from).  You may
> also send the HELP command for other information
> (like subscribing).
> 
> 
>
_________________________________________________________
> Do You Yahoo!?
> Get your free @yahoo.com address at
> http://mail.yahoo.com
> 
> -- 
> Please see the official ORACLE-L FAQ:
> http://www.orafaq.com
> -- 
> Author: K Gopalakrishnan
>   INET: [EMAIL PROTECTED]
> 
> Fat City Network Services    -- (858) 538-5051  FAX:
> (858) 538-5051
> San Diego, California        -- Public Internet
> access / Mailing Lists
>
--------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an
> E-Mail message
> to: [EMAIL PROTECTED] (note EXACT spelling of
> 'ListGuru') and in
> the message BODY, include a line containing: UNSUB
> ORACLE-L
> (or the name of mailing list you want to be removed
> from).  You may
> also send the HELP command for other information
> (like subscribing).


__________________________________________________
Do You Yahoo!?
Get email alerts & NEW webcam video instant messaging with Yahoo!
Messenger. http://im.yahoo.com
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: mohammed bhatti
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Rajesh Dayal
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).

Reply via email to