Tanel, you are a genuine treasure and a very nice addition to this list.

--
Mladen Gogala
Oracle DBA 



> -----Original Message-----
> From: [EMAIL PROTECTED] [mailto:[EMAIL PROTECTED] On 
> Behalf Of Tanel Poder
> Sent: Friday, September 19, 2003 12:55 PM
> To: Multiple recipients of list ORACLE-L
> Subject: Re: sizing sort_area_size
> 
> 
> Hi!
> 
> Just few additions about 9i's nice features for tuning sorts, 
> hash joins & other work area operations:
> 
> SQL> select n.name,s.value
>   2  from v$statname n,v$sesstat s
>   3  where n.statistic#=s.statistic#
>   4  and n.name like '%workarea executions%'
>   5  and s.sid in (
>   6      select sid from v$session
>   7      where audsid=sys_context('USERENV','SESSIONID')
>   8  );
> 
> NAME                                                          
>         VALUE
> --------------------------------------------------------------
> -- ----------
> workarea executions - optimal                                 
>           136
> workarea executions - multipass                               
>             0
> workarea executions - onepass                                 
>             1
> 
> Optimal means in-memory work area operations (sorts, hash 
> joins, bitmap merges, etc.), onepass & multipass mean on disk 
> operations. In OLAP and reporting environments, on-disk 
> sorting or hasing is often unavoidable, but you should try to 
> keep your sorts away from multipass executions, this will 
> heavily hit your TEMP TS IO (sort runs can't be merged in 
> sort area in one run, several runs needed) also CPU (some 
> data comparisions have to be done semi-redundantly). The 
> larger your sort_area_size, the smaller is the chance you'll 
> need multipass sorting. (v$sql_workarea_histograms table can 
> be useful for finding optimal tradeoff between PGA memory 
> usage and temp ts IO on system level. On session level, 
> v$sql_ workarea and v$sql_workare_active contain very 
> interesting statistics).
> 
> Tanel.
> 
> ----- Original Message ----- 
> To: "Multiple recipients of list ORACLE-L" <[EMAIL PROTECTED]>
> Sent: Friday, September 19, 2003 5:24 PM
> 
> 
> > The following query will give you an idea how to tune sort 
> area size:
> >   1  select n.name,s.value
> >   2  from v$statname n,v$sesstat s
> >   3  where n.statistic#=s.statistic#
> >   4        and n.name like '%sort%'
> >   5        and s.sid in (select sid from v$session
> >   6*                     where 
> audsid=sys_context('USERENV','SESSIONID'))
> > SQL> /
> >
> > NAME
> VALUE
> > ---------------------------------------------------------------- 
> > ---------
> -
> > sorts (memory)
> 26
> > sorts (disk)
> 0
> > sorts (rows)
> 87
> >
> > SQL>
> >
> > --
> > Mladen Gogala
> > Oracle DBA
> >
> >
> >
> > > -----Original Message-----
> > > From: [EMAIL PROTECTED] 
> [mailto:[EMAIL PROTECTED] On Behalf 
> > > Of [EMAIL PROTECTED]
> > > Sent: Thursday, September 18, 2003 3:10 PM
> > > To: Multiple recipients of list ORACLE-L
> > > Subject: sizing sort_area_size
> > >
> > >
> > > I have been doing some alter sessions to improve performance of 
> > > gigabyte sized 'minus' operations. How do I tell if this 
> is helping 
> > > other than completion time?
> > >
> > > I believe that if LIOs to PIOs ratio improves with the SAME query 
> > > then sort_area_size has helped right?(notice Im not trying to 
> > > improve my cache/hit ratio).
> > >
> > > I get this from v$sess_io.
> > >
> > > how do I tell how much temp tablespace my session uses? I 
> cant find 
> > > a statistic for it? I see that I used up all my PGA since 
> PGA size 
> > > and PGA max size are equal in v$sesstat.
> > >
> > > anything else I can look at?
> > >
> > > --
> > > Please see the official ORACLE-L FAQ: http://www.orafaq.net
> > > -- 
> > > Author: <[EMAIL PROTECTED]
> > >   INET: [EMAIL PROTECTED]
> > >
> > > Fat City Network Services    -- 858-538-5051 
> http://www.fatcity.com
> > > San Diego, California        -- Mailing list and web 
> hosting services
> > > 
> --------------------------------------------------------------------
> > > -
> > > 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).
> > >
> >
> >
> >
> >
> > Note:
> > This message is for the named person's use only.  It may contain
> confidential, proprietary or legally privileged information.  
> No confidentiality or privilege is waived or lost by any 
> mistransmission.  If you receive this message in error, 
> please immediately delete it and all copies of it from your 
> system, destroy any hard copies of it and notify the sender.  
> You must not, directly or indirectly, use, disclose, 
> distribute, print, or copy any part of this message if you 
> are not the intended recipient. Wang Trading LLC and any of 
> its subsidiaries each reserve the right to monitor all e-mail 
> communications through its networks.
> > Any views expressed in this message are those of the individual 
> > sender,
> except where the message states otherwise and the sender is 
> authorized to state them to be the views of any such entity.
> >
> > --
> > Please see the official ORACLE-L FAQ: http://www.orafaq.net
> > -- 
> > Author: Mladen Gogala
> >   INET: [EMAIL PROTECTED]
> >
> > Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
> > San Diego, California        -- Mailing list and web 
> hosting services
> > 
> ---------------------------------------------------------------------
> > 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.net
> -- 
> Author: Tanel Poder
>   INET: [EMAIL PROTECTED]
> 
> Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
> San Diego, California        -- Mailing list and web hosting services
> ---------------------------------------------------------------------
> 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).
> 




Note:
This message is for the named person's use only.  It may contain confidential, 
proprietary or legally privileged information.  No confidentiality or privilege is 
waived or lost by any mistransmission.  If you receive this message in error, please 
immediately delete it and all copies of it from your system, destroy any hard copies 
of it and notify the sender.  You must not, directly or indirectly, use, disclose, 
distribute, print, or copy any part of this message if you are not the intended 
recipient. Wang Trading LLC and any of its subsidiaries each reserve the right to 
monitor all e-mail communications through its networks.
Any views expressed in this message are those of the individual sender, except where 
the message states otherwise and the sender is authorized to state them to be the 
views of any such entity.

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Mladen Gogala
  INET: [EMAIL PROTECTED]

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
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