2012-03-02 Created By BaoXinjian
一、摘要
查看目前正在running的并发程式。
再确认并发程式运行的时间较长的程式,通过监控查看运行时间较长的并发程式。
通过v$session or v$session_longops查看当前session的sql和wait event。
二、具体SQL
1. 查看目前在运行中的并发程式
Looking on how to check long running concurrent request in Oracle Apps 11i or R12? Here’s the overview of the SQL query script to detect the session information of each program.
First you need to get the listing of running concurrent request in Oracle Apps 11i or R12. You can use the SQL query script as below to obtain the list of running request.
/* 查看目前运行的并发程式 */ SELECT a.request_id, a.oracle_process_id "SPID", frt.responsibility_name, c.concurrent_program_name || ': ' || ctl.user_concurrent_program_name, a.description, a.ARGUMENT_TEXT, b.node_name, b.db_instance, a.logfile_name, a.logfile_node_name, a.outfile_name, q.concurrent_queue_name, a.phase_code, a.status_code, a.completion_text, actual_start_date, actual_completion_date, fu.user_name, (NVL (actual_completion_date, SYSDATE) - actual_start_date) * 1440 mins, (SELECT AVG(NVL (a2.actual_completion_date - a2.actual_start_date, 0)) * 1440 avg_run_time FROM APPLSYS.fnd_Concurrent_requests a2, APPLSYS.fnd_concurrent_programs c2 WHERE c2.concurrent_program_id = c.concurrent_program_id AND a2.concurrent_program_id = c2.concurrent_program_id AND a2.program_application_id = c2.application_id AND a2.phase_code || '' = 'C') avg_mins, ROUND ( (actual_completion_date - requested_start_date), 2) * 24 duration_in_hours FROM APPLSYS.fnd_Concurrent_requests a, APPLSYS.fnd_concurrent_processes b, applsys.fnd_concurrent_queues q, APPLSYS.fnd_concurrent_programs c, APPLSYS.fnd_concurrent_programs_tl ctl, apps.fnd_user fu, apps.FND_RESPONSIBILITY_TL frt WHERE a.controlling_manager = b.concurrent_process_id AND a.concurrent_program_id = c.concurrent_program_id AND a.program_application_id = c.application_id AND a.phase_code = 'R' AND a.status_code = 'R' AND b.queue_application_id = q.application_id AND b.concurrent_queue_id = q.concurrent_queue_id AND ctl.concurrent_program_id = c.concurrent_program_id AND a.requested_by = fu.user_id AND a.responsibility_id = frt.responsibility_idORDER BY a.actual_start_date DESC
2. 查看并发程式对应的session
Based on the SPID associated to each running request, query the v$session or v$session_longops table to see what is the request id doing in the backend.
/* 查看并发程式对应的session */ SELECT b.sid, b.serial#, a.spid, b.program, b.osuser, b.machine, b.type, b.event, b.action, b.p1text, b.p2text, b.p3text, b.state, c.sql_text, b.logon_time FROM v$process a, v$session b, v$sqltext c WHERE a.addr = b.paddr AND b.sql_hash_value = c.hash_value AND b.STATUS = 'ACTIVE' AND a.spid = '11696'ORDER BY a.spid, c.piece
注意:Replace v$session with gv$session if the database is running on RAC environment. Enable or set trace if you wish to know more details on the session.
Thanks and Regards