|
 |
|
Oracle recursive SQL and STATSPACK
Oracle Database Tips by Donald Burleson |
Question: Is it true that anything done inside of a server-side
procedure gets recorded under "recursive CPU" in Statspack?
For example, if I bundle some queries together on the host side within a
stored procedure (rather than issue separate queries from a client process),
will the "Top 5 Wait Events" be skewed as a result?
Answer: This is a very important question and
it deserves a detailed answer. For complete details, see my book
"Oracle
Tuning: The Definitive Reference".
In general a ?recursive SQL? is additional "hidden" SQL
that is issued for internal Oracle functions such as re-caching paged-out data
from the dictionary cache, but we also see recursive SQL for these items:
-
Parsing a new SQL statement (validate table & column
names, check security)
-
Space management functions required to service DDL
(create table)
-
Trigger code
-
SQL within PL/SQL (functions and stored procedures)
-
Referential integrity checks
The only problem with lots of SQL within stored procedures
and functions is that it is reported as "recursive CPU" in a STATSPACK report.
It's still accurate, but we do not see the individual SQL represented at the
same granular-level as independent SQL statements.
The STATSPACK report mentions the issue of recursive SQL in
the SQL section where the "%total" metric may be over 100%:
"Note that
resources reported for PL/SQL includes the resources used by all SQL
statements called within the PL/SQL code.
As
individual SQL statements are also reported, it is possible and valid for
the summed total % to exceed 100."
Skewed top-5 wait events for recursive SQL?
Does recursive SQL factor in the top-5 wait events for CPU
consumption? Yes. CPU consumption is measured even though the single
invocation of a stored procedure may have a dozen CPU-intensive SQL statements
within the body of the procedure.
To verify that a top-5 wait event of "CPU" is not caused by
"bad" recursive SQL, you need to explore the details for "parse time CPU", "CPU
used by this session" and "recursive CPU usage".
In other words, a top-5 wait event may not show "CPU other"
as a major event, and it can be misleading when you don't see CPU in the top-5
timed events because it is hidden.
CPU Other = CPU used by this session - parse time CPU -
recursive CPU usage
This
article has an excellent example of computing recursive CPU, and how the
top-5 wait events can be misleading.
SQL Queries for recursive CPU usage
Outside of a STATSPACK report, you can query for recursive
CPU usage with this query:
select *
from
(select
b.sid sid,
decode (b.username,null,e.name,b.username) user_name,
d.spid os_id,
b.machine machine_name,
to_char(logon_time,'dd-mon-yy hh:mi:ss pm') logon_time,
sum(decode(c.name,'recursive cpu usage',value,0))
recursive_cpu,
sum(decode(c.name,'cpu used by this session',value,0)) -
sum(decode(c.name,'parse time cpu',value,0)) -
sum(decode(c.name,'recursive cpu usage',value,0))
other_cpu
from
sys.v_$sesstat a,
sys.v_$session b,
sys.v_$statname c,
sys.v_$process d,
sys.v_$bgprocess e
where
a.statistic#=c.statistic# and
b.sid=a.sid and
d.addr = b.paddr and
e.paddr (+) = b.paddr and
c.NAME in (
See
code depot for full script
group by
b.sid,
d.spid,
decode (b.username,null,e.name,b.username),
b.machine,
to_char(logon_time,'dd-mon-yy hh:mi:ss pm')
order by
6 desc);
Here are examples of recursive SQL from a real STATSPACK
report:
select obj#,type#,ctime,mtime,stime,status,dataobj#,flags,oid$,
spare1, spare2 from obj$
where owner#=:1 and name=:2 and namespa
ce=:3 and remoteowner is
null and linkname is null
select col#, grantee#,
privilege#,max(mod(nvl(option$,0),2)) fro
m objauth$ where obj#=:1 and
col# is not null group by privilege
#, col#, grantee# order by
col#, grantee#
update sys.col_usage$ set
equality_preds = equality_preds
+ decode(bitand(:flag,1),0,0,1),
equijoin_preds = equijoi
n_preds + decode(bitand(:flag,2),0,0,1),
nonequijoin_preds
= nonequijoin_preds +
decode(bitand(:flag,4),0,0,1), range_pre
ds = range_preds
+ decode(bitand(:flag,8),0,0,1),
select name,intcol#,segcol#,type#,length,nvl(precision#,0),decod
e(type#,2,nvl(scale,-127/*MAXSB1MINAL*/),178,scale,179,scale,180
,scale,181,scale,182,scale,183,scale,231,scale,0),null$,fixedsto
rage,nvl(deflength,0),default$,rowid,col#,property,
nvl(charseti
d,0),nvl(charsetform,0),spare1,spare2,nvl(spare3,0) from col$
 |
If you like Oracle tuning, see the book "Oracle
Tuning: The Definitive Reference", with 950 pages of tuning tips and
scripts.
You can buy it direct from the publisher for 30%-off and get
instant access to the code depot of Oracle tuning scripts. |

|
|