Find what each Oracle process is doing
Here is a handy script that will correlate the operating system process with the Oracle process.
Here is a handy script that will correlate the operating system process with the Oracle process. You'll also be...
Continue Reading This Article
Enjoy this article as well as all of our content, including E-Guides, news, tips and more.
able to see the most current SQL run by that process. Therefore, if you find an OS process is consuming significant resources in a monitoring tool like top, you can run this SQL, correlate the OS process to the Oracle session identifier and see the most recent SQL executed. It works on all versions on or above 8.0.5.
set lines 180 pages 1000 column pu format a8 heading 'O/S|Login|ID' column su format a8 heading 'Oracle|User ID' column stat format a8 heading 'Session|Status' column ssid format 999999 heading 'Oracle|Session|ID' column sser format 999999 heading 'Oracle|Serial|No' column spid format 999999 heading 'UNIX|Process|ID' column txt format a28 heading 'Current Statment' spool pid_sid.lst SELECT p.username pu, s.username su, s.status stat, s.sid ssid, s.serial# sser, lpad(p.spid,7) spid, substr(sa.sql_text,1,540) txt FROM v$process p, v$session s, v$sqlarea sa WHERE p.addr=s.paddr AND s.username is not null AND s.sql_address=sa.address(+) AND s.sql_hash_value=sa.hash_value(+) ORDER BY 1,2,7 / spool off
Reader Feedback
Ravi writes: Good SQL. You can enhance it further by adding s.osuser to reflect the current OS user.
Roger M. writes: This is a great tip. I spent hours developing something similar. We are running Oracle Applications in a 2-tier environment; i.e., a database tier and forms tier. My stripped-down version of the tip allows you to plug in the PID from a top command on Unix to display information about the process, including the Oracle Application User if available. My SQL requires one additional view to gather information from the Oracle Application tables:
CREATE OR REPLACE VIEW BB_DBA_CURRENT_SESSIONS_V ( USER_NAME, USER_ID, SID, ORACLE_PROCESS, UNIX_PROCESS, SERIAL#, AUDSID ) AS ( SELECT DISTINCT u.user_name, u.user_id, s.sid, p.pid, p.spid, s.serial#, s.audsid FROM v$process p, v$session s,apps.fnd_logins l,apps.fnd_user u WHERE p.addr=s.paddr AND l.pid=p.pid AND l.spid=s.process AND l.user_id=u.user_id ) --Run TOP command on Unix processor. The PID from the Unix process is the input for variable -- in either of the statements below: --data base tier SELECT s.PADDR,s.SID,s.SERIAL#,s.USERNAME,s.OSUSER,s.PROGRAM, p.SPID, p.pid, u.USER_NAME FROM v$session s, v$process p, bb_dba_current_sessions_v u WHERE p.spid = &proc_unix AND p.addr = s.paddr AND u.sid(+) = s.sid --middle tier or parallel concurrent manager SELECT s.PADDR,s.SID,s.SERIAL#,s.USERNAME,s.OSUSER,s.PROGRAM, p.SPID, p.pid, u.USER_NAME, s.process FROM v$session s, v$process p, bb_dba_current_sessions_v u WHERE s.process = '&process_id' AND p.addr = s.paddr AND u.sid(+) = s.sid --run this query with sid from queries above to see the sql being executed SELECT a.sid, a.username, s.sql_text FROM v$session a, v$sqltext s WHERE a.sql_address = s.address AND a.sql_hash_value = s.hash_value AND a.sid = &sid ORDER BY a.username, a.sid, s.piece;
For More Information
- Feedback: E-mail the editor with your thoughts about this tip.
- More tips: Hundreds of free Oracle tips and scripts.
- Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
- Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
- Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
- Best Web Links: Oracle tips, tutorials, and scripts from around the Web.