sp_monitor

Description

Displays statistics about Adaptive Server.

Syntax

sp_monitor syntax is divided by command type for clarity, since many of the types have parameters of their own. The following code paragraph shows the syntax of the stored procedure as a whole, followed by the syntax of each command type interface.

sp_monitor [connection, [cpu | diskio | elapsed time]]  
	[event, [spid ]] [procedure, [dbname, [procname, 
	[, summary | detail]]]] [enable] [disable] 
	[statement, [cpu | diskio | elapsed time]] [help], 
	[connection | statement | procedure | event | deadlock | procstack]

The syntax for sp_monitor 'connection':

sp_monitor [connection, [cpu | diskio | elapsed time ]]

The syntax for sp_monitor 'event':

sp_monitor [event, [spid]]

The syntax for sp_monitor 'procedure':

sp_monitor [ procedure, [dbname , [procname, [, summary | detail]]]]

Parameters

connection

displays information on each connection. connection uses the following monitoring tables:

  • monProcessSQLText

  • monProcessActivity

cpu | diskio | elapsed time

these parameters order the output of sp_monitor connection. cpu indicates the amount of CPU time consumed by each different connection. diskio indicates the number of physical reads performed by each connection. elapsed time indicates the sum of the CPU time and the wait times for each connection.

event

displays three possibilities. When you specify:

  • No option – only user tasks are displayed.

  • sp_monitor, event, "-1" – wait information about all tasks, both user and system, is displayed.

  • sp_monitor, event, "spid" – wait information pertaining to only the specified server process ID is displayed.

spid

allows you to obtain event information for a specific task by entering its spid. You must specify the numeric value of spid within quotation marks.

procedure

displays statistics about stored procedures:

  • ProcName – the stored procedure being monitored.

  • DBNAME – the database in which the stored procedure is located.

  • NumExecs – the approximate number of executions of this specific stored procedure.

  • AvgCPUTime – the average CPU time that it takes for the stored procedure to execute.

  • AvgPhysicalReads – the average number of disk reads performed by the stored procedure.

  • AvgLogicalReads – the average number of logical reads performed by the stored procedure.

  • AvgMemUsed_KB – the average amount of memory in KB used by the stored procedure.

procedure uses the monSysStatement monitoring table.

dbname

displays information on procedures for the specified database.

procname

displays information on the specified procedure.

summary | detail

displays either summary information, which provides an average of all instances of the procedure, or detailed information, which provides information on every instance of the stored procedure.

enable

enables the new options for sp_monitor. It turns on the configuration parameter required to begin monitoring.

disable

disables monitoring.

statement

displays information on each statement. statement uses the following monitoring tables:

  • monProcessSQLText

  • monProcessStatement

cpu | diskio | elapsed time

These parameters help order the output of sp_monitor statement. cpu indicates the the cpu time consumed by different statements. diskio indicates the number of physical reads done by different statements. elapsed time indicates the sum of the CPU time and the wait times for different statements.

help

displays the syntax and examples for sp_monitor, and also reports extensive information on using this procedure for deadlock analysis:

sp_monitor 'help', 'deadlock'

The help option also provides command-specific examples.

deadlock

tells sp_monitor to process historical data from the monDeadlock table, and prints out a block of output for each instance of deadlock.

procstack

examines the execution context of a task, including that of a deeply nexted stored procedure. The stack of procedures executed is extracted from the monProcessProcedures monitoring table.

Examples

Example 1

Reports information about how busy Adaptive Server has been:

sp_monitor
last_run               current_run          seconds 
-------------------    -------------------  --------- 
Jan 29 1987 10:11AM    Jan 29 1987 10:17AM  314

cpu_busy           io_busy     idle 
---------------    ---------   -------------- 
4250(215)-68%      67(1)-0%    109(100)-31% 

packets_received       packets_sent    packet_errors 
----------------       ------------    ------------ 
781(15)                10110(9596)     0(0) 

total_read     total_write total_errors    connections 
-----------    -------------------------   ----------- 
394(67)        5392(53)    0(0)            15(1) 

Example 2

Shows how to display information about connections:

1> sp_monitor "connection"
2> go
spid    LoginName    ElapsedTime  LocksHeld  SQLText  
----    ---------    -----------  ---------  -----------------
12      sa           90300        2          exec get_employee_salaries
27      sa           17700        1          exec get_employee_perks

By default, the output by default is sorted in the descending order of the ElapsedTime.

Example 3

Identifies the connections performing the most physical reads:

1> sp_monitor "connection","diskio"
2> go
spid  LoginName  Physical_Reads  LocksHeld  SQLText 
----  ---------  --------------  ---------  -------------------------- 
12    sa         117             2          exec get_employee_salaries 
27    sa         1               0          exec get_employee_perks 

Example 4

Displays information about each statement:

1> sp_monitor "statement"
2> go
spid   LoginName   ElapsedTime   SQLText
----   ---------   -----------   -------------------------- 
12     sa          100           exec get_employee_salaries 

Example 5

Displays the events each task spent time waiting for and the duration of the wait, reported in descending order of wait times:

1> sp_monitor "event"
2> go
SPID   WaitTime    Description 
------ ----------- ------------------------------------------ 
6      108200      hk: pause for some time 
29     108200      waiting for incoming network data 
10     107800      waiting while allocating new client socket 
15     17100       waiting for network send to complete 
14     5900        waiting for CTLIB event to complete 
14     400         waiting for disk write to complete 
7      200         hk: pause for some time 
7      100         waiting on run queue after yield 
12     100         waiting for network send to complete 

Example 6

Displays event data for spid 14:

1> sp_monitor "event","14"
2> go
WaitTime    Description 
----------- ----------------------------------- 
9000 waiting for CTLIB event to complete 
600 waiting for disk write to complete 
200 waiting for disk write to complete 
100 waiting on run queue after yield 
100 wait for buffer write to complete

Example 7

Provides a summary of most recently run procedures, sorted in descending order of average elapsed time. This example provides historical monitoring information rather than the current state.

1> sp_monitor "procedure"
2> go

Average Procedure Statistics
============================

ProcName       DBName    AvgElapsedTime   AvgCPUTime  AvgWaitTime AvgPhysicalReads AvgLogicalReads AvgPacketsSent NumExecs 
-----------------------------------------------------------------------neworder_remote   tpcc   1833     16    1083     26   96    0     6
neworder_local    tpcc   1394     13    1181     31   122   0     38
tc_startup        tpcc   1220     3     1157     0    3     0     59
delivery          tpcc   1000     0     800      23   49    0     2

Usage

NoteBefore using the new parameters associated with sp_monitor, you must set up monitoring tables and the related stored procedures needed to enable these options, which are part of the installmontables script. For more information, see “Installing Monitoring Tables” in Performance and Tuning: Monitoring and Analyzing.

Permissions

You must have mon_role permissions to execute sp_monitor. For more information see “Monitoring Tables” Performance and Tuning: Monitoring and Analyzing.

Auditing

Values in event and extrainfo columns from the sysaudits table are:

Event

Audit option

Command or access audited

Information in extrainfo

38

exec_procedure

Execution of a procedure

  • Roles – Current active roles

  • Keywords or options – NULL

  • Previous value – NULL

  • Current value – NULL

  • Other information – All input parameters

  • Proxy information – Original login name, if set proxy in effect

See also

System procedures sp_who