Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Monitor Oracle Connections Tips

Oracle Database Tips by Donald BurlesonMarch 12, 2013

Question:  I need to know how I can count the number of connections to my Oracle database.  I need the connection count from Linux/UNIX.  Also, how can I monitor the number of connection sessions within Oracle?

Answer:  There are two says to monitor Oracle connections, within Oracle and outside of Oracle with the "ps" command.  Oracle provides the v$process and v$session views within Oracle to get detailed information about Oracle connected sessions. You can also see the UNIX process IDs for all executing processes on your database server if you are not using the multi-threaded server (shared servers).

The following script is extremely useful for showing all dedicated connections to Oracle. Please note that this script displays the UNIX process ID (PID) and also gives information about the executing program. It is also possible to enhance this script to show the actual SQL statement by joining into the v$sql view.

--**************************************************************
-- session.sql

-- count and monitor the number of connected Oracle sessions

rem session.sql - displays all connected sessions
set echo off;
set termout on;
set linesize 80;
set pagesize 60;
set newpage 0;

select
rpad(c.name||':',11)||rpad(' current logons='||
(to_number(b.sessions_current)),20)||'cumulative logons='||
rpad(substr(a.value,1,10),10)||'highwater mark='||
b.sessions_highwater Information
from
v$sysstat a,
v$license b,
v$database c
see code depot for full scripts
where
a.name = 'logons cumulative'
;

ttitle "dbname Database|UNIX/Oracle Sessions";

set heading off;
select 'Sessions on database '||substr(name,1,8) from v$database;
set heading on;
select
substr(a.spid,1,9) pid,
substr(b.sid,1,5) sid,
substr(b.serial#,1,5) ser#,
substr(b.machine,1,6) box,
substr(b.username,1,10) username,
substr(b.osuser,1,8) os_user,
substr(b.program,1,30) program
from
v$session b,
v$process a
where
b.paddr = a.addr
and
type='USER'
order by
spid
;


ttitle off;
set heading off;
select 'To kill, enter SQLPLUS> ALTER SYSTEM KILL SESSION',
''''||'SID, SER#'||''''||';' from dual;
spool off;

Here is a sample listing from running this script. Please note that it begins by displaying summaries of all current, cumulative, and the high-water mark for logons before displaying the details for each session:

SQL> @session

INFORMATION
----------------------------------------------------------------------------
PRODLIVE: current logons=14 cumulative logons=166 highwater mark=14

UNIX/Oracle Sessions
Sessions on database PEMINE
Sat Oct 13 page 1
dbname Database
UNIX/Oracle Sessions

PID SID SER# BOX USERNAME OS_USER PROGRAM
--------- ----- ----- ------ ---------- -------- ---------------------------
1005 14 124 hawk CASH rhayes runmenu50@hawk
1139 13 39 hawk STAFF clarson runmenu50@hawk
1526 11 1550 hawk BURLESON burleson sqlplus@hawk
1690 15 47 hawk CASH kjoslin runmenu50@hawk
2482 16 263 hawk STAFF brobinso runmenu50@hawk
2568 17 26 BELLEV SCHED Bellmont F45RUN32.EXE
27180 9 228 hawk PATIENT daemon sqlplus@hawk
29316 8 3238 hawk CASH jdutcher runmenu50@hawk
29440 12 137 hawk CASH lchapman runmenu50@hawk
3231 18 173 hawk STAFF jhahn runmenu50@hawk
3241 19 39 BELLEV SCHED dplueger F45RUN32.EXE
273 20 11 BELLEV SCHED dplueger R25SRV32.EXE

To kill, enter SQLPLUS> ALTER SYSTEM KILL SESSION 'SID, SER#';
SQL>

If you want to move outside of Oracle and monitor connections for the session at the UNIX level, you must correlate the Oracle PID with the UNIX PID. To see details of these processes, you can write an Oracle script to filter the UNIX ps output to only include these processes:

ps_pid.ksh

#/bin/ksh
sqlplus cpi/oracle@prodlive<<!
set pages 999
set feedback off
set echo off
set heading off

spool /tmp/run_pid.ksh

select
'ps -ef|grep '||spid||'grep –v grep'
from
v\$process
see code depot for full scripts
where
spid is not NULL
;

spool off;
!

# Execute the UNIX commands . . . .
chmod +x /tmp/*.ksh

/tmp/run_pid.ksh

Here is the output from this script. As you see, the SQL*Plus script builds the UNIX ps command for the Oracle PIDs and then executes the command:

root> /tmp/run_pid.ksh
jjahn 3231 3129 0 08:12:17 - 0:00 oraclePA
bbeckero 2482 2377 0 07:59:26 - 0:00 oraclePA
scarf 2376 785 0 07:59:03 ttyp9 0:00 telnetd
brobins 2377 2376 0 07:59:04 ttyp9 0:01 runmenu50 pamenu
monte 1372 1 0 Sep 21 - 5:58 /opt/hpnp/bin/hpnpd
jmels 1886 1878 0 Sep 21 ttyp1 0:00 tee -a

This script allows you to see the start time for the UNIX connection and also see the cumulative CPU consumption for each task.  This is a great script for monitoring Oracle connections over time.  Also see the code depot for a full set of Oracle session counting and monitoring scripts.


 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster