This is a simple script that I wrote more than 20 years ago (for 8.1.7.4 apparently) to get the session wait event figures from parallel query slaves as they were running. I’m posting it now because there’s a question on the Oracle Database Forum where it would be useful as a way for checking for performance problems in a long-running CTAS.
Oracle gives us the view v$px_session to link together the query co-ordinator with the parallel query slaves, and it gives us v$px_sesstat to report the linked session activity stats, but it doesn’t gives us a view to link together the session events for the multiple sessions, so this query simply joins v$px_session to v$session_events to produce that result:
rem
rem Script: px_waits.sql
rem Author: Jonathan Lewis
rem Dated: Mar 2001
rem Purpose: Report events for PX execution
rem
rem Last tested:
rem 19.3.0.0
rem
rem Notes:
rem Note that the co-ordinator can be on a different instance
rem in parallel server systems. To cater for an oddity of the
rem qcinst report, we need the current instance number in case
rem the QC is on the current machine.
rem
rem If the co-ordinator is present, then it appears last on the list
rem for a server group.
rem
column instance_number new_value m_inst
select instance_number from v$instance;
set linesize 120
set pagesize 60
set trimspool on
set tab off
set verify off
spool px_waits
break -
on qcsid skip 1 -
on server_group -
on degree -
on server_set -
on sid -
on server# skip 1
column event format a32
column qcsid format a6 heading 'Coord'
column server_group format 999 heading 'Grp'
column degree format a5 heading 'Deg' noprint
column server_set format 999 heading 'Set' noprint
column server# format 999 heading 'Sno'
column sid format 9999 heading 'SID'
column name format a32 heading 'Statistic'
column value format 99,999,999 heading 'value'
select
ss.qcsid || '/' || nvl(ss.qcinst_id,&m_inst) qcsid,
ss.server_group,
decode(degree,
null,null,
ss.degree || '/' || ss.req_degree
) degree,
ss.server_set,
ss.server#,
ss.sid,
se.event,
se.total_waits,
se.time_waited
from
v$px_session ss,
v$session_event se
where
se.sid = ss.sid
order by
ss.qcsid,
ss.server_group,
ss.server_set,
ss.server#,
se.event
;
clear columns
clear breaks
set verify on
spool off
See also: Parallel Activity for the session activity stats report.
[…] also: Parallel Inactivity for a simple script reporting wait […]
Pingback by Parallel Activity | Oracle Scratchpad — April 7, 2022 @ 5:09 pm BST Apr 7,2022 |
[…] showing all the hints, their inverses, and the level(s) for which they’re relevant. Parallel Wait Events: simple listing for the wait events for all the processes involved in a parallel query. Parallel […]
Pingback by Simple scripts | Oracle Scratchpad — April 7, 2022 @ 5:20 pm BST Apr 7,2022 |