1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>24.2.The Statistics Collector</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="monitoring.html" title="Chapter24.Monitoring Database Activity">
<link rel="prev" href="monitoring.html" title="Chapter24.Monitoring Database Activity">
<link rel="next" href="monitoring-locks.html" title="24.3.Viewing Locks">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="monitoring-stats"></a>24.2.The Statistics Collector</h2></div></div></div>
<a name="id671791"></a><p> <span class="productname">PostgreSQL</span>'s <em class="firstterm">statistics collector</em>
is a subsystem that supports collection and reporting of information about
server activity. Presently, the collector can count accesses to tables
and indexes in both disk-block and individual-row terms. It also supports
determining the exact command currently being executed by other server
processes.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="monitoring-stats-setup"></a>24.2.1.Statistics Collection Configuration</h3></div></div></div>
<p> Since collection of statistics adds some overhead to query execution,
the system can be configured to collect or not collect information.
This is controlled by configuration parameters that are normally set in
<code class="filename">postgresql.conf</code>. (See <a href="runtime-config.html" title="Chapter17.Server Configuration">Chapter17, <i>Server Configuration</i></a> for
details about setting configuration parameters.)
</p>
<p> The parameter <a href="runtime-config-statistics.html#guc-stats-start-collector">stats_start_collector</a> must be
set to <code class="literal">true</code> for the statistics collector to be launched
at all. This is the default and recommended setting, but it may be
turned off if you have no interest in statistics and want to
squeeze out every last drop of overhead. (The savings is likely to
be small, however.) Note that this option cannot be changed while
the server is running.
</p>
<p> The parameters <a href="runtime-config-statistics.html#guc-stats-command-string">stats_command_string</a>,
<a href="runtime-config-statistics.html#guc-stats-block-level">stats_block_level</a>, and <a href="runtime-config-statistics.html#guc-stats-row-level">stats_row_level</a> control how much information is
actually sent to the collector and thus determine how much run-time
overhead occurs. These respectively determine whether a server
process sends its current command string, disk-block-level access
statistics, and row-level access statistics to the collector.
Normally these parameters are set in <code class="filename">postgresql.conf</code>
so that they apply to all server processes, but it is possible to
turn them on or off in individual sessions using the <a href="sql-set.html">SET</a> command. (To prevent
ordinary users from hiding their activity from the administrator,
only superusers are allowed to change these parameters with
<code class="command">SET</code>.)
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> Since the parameters <code class="varname">stats_command_string</code>,
<code class="varname">stats_block_level</code>, and
<code class="varname">stats_row_level</code> default to <code class="literal">false</code>,
very few statistics are collected in the default
configuration. Enabling one or more of these configuration
variables will significantly enhance the amount of useful data
produced by the statistics collector, at the expense of
additional run-time overhead.
</p>
</div>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="monitoring-stats-views"></a>24.2.2.Viewing Collected Statistics</h3></div></div></div>
<p> Several predefined views, listed in <a href="monitoring-stats.html#monitoring-stats-views-table" title="Table24.1.Standard Statistics Views">Table24.1, “Standard Statistics Views”</a>, are available to show the results
of statistics collection. Alternatively, one can
build custom views using the underlying statistics functions.
</p>
<p> When using the statistics to monitor current activity, it is important
to realize that the information does not update instantaneously.
Each individual server process transmits new block and row access counts to
the collector just before going idle; so a query or transaction still in
progress does not affect the displayed totals. Also, the collector itself
emits a new report at most once per <code class="varname">PGSTAT_STAT_INTERVAL</code>
milliseconds (500 unless altered while building the server). So the
displayed information lags behind actual activity. Current-query
information is reported to the collector immediately, but is still subject
to the <code class="varname">PGSTAT_STAT_INTERVAL</code> delay before it becomes
visible.
</p>
<p> Another important point is that when a server process is asked to display
any of these statistics, it first fetches the most recent report emitted by
the collector process and then continues to use this snapshot for all
statistical views and functions until the end of its current transaction.
So the statistics will appear not to change as long as you continue the
current transaction.
This is a feature, not a bug, because it allows you to perform several
queries on the statistics and correlate the results without worrying that
the numbers are changing underneath you. But if you want to see new
results with each query, be sure to do the queries outside any transaction
block.
</p>
<div class="table">
<a name="monitoring-stats-views-table"></a><p class="title"><b>Table24.1.Standard Statistics Views</b></p>
<div class="table-contents"><table summary="Standard Statistics Views" border="1">
<colgroup>
<col>
<col>
</colgroup>
<thead><tr>
<th>View Name</th>
<th>Description</th>
</tr></thead>
<tbody>
<tr>
<td><code class="structname">pg_stat_activity</code></td>
<td>One row per server process, showing database OID, database name,
process <acronym class="acronym">ID</acronym>, user OID, user name, current query, time at
which the current query began execution, time at which the process
was started, and client's address and port number. The columns
that report data on the current query are only available if the
parameter <code class="varname">stats_command_string</code> has been
turned on. Furthermore, these columns read as null unless the
user examining the view is a superuser or the same as the user
owning the process being reported on. (Note that because of the
collector's reporting delay, the current query will only be
up-to-date for long-running queries.)</td>
</tr>
<tr>
<td><code class="structname">pg_stat_database</code></td>
<td>One row per database, showing database OID, database name,
number of active server processes connected to that database,
number of transactions committed and rolled back in that database,
total disk blocks read, and total buffer hits (i.e., block
read requests avoided by finding the block already in buffer cache).
</td>
</tr>
<tr>
<td><code class="structname">pg_stat_all_tables</code></td>
<td>For each table in the current database (including TOAST tables),
the table OID, schema and table name, number of sequential
scans initiated, number of live rows fetched by sequential
scans, number of index scans initiated (over all indexes
belonging to the table), number of live rows fetched by index
scans,
and numbers of row insertions, updates, and deletions.</td>
</tr>
<tr>
<td><code class="structname">pg_stat_sys_tables</code></td>
<td>Same as <code class="structname">pg_stat_all_tables</code>, except that only
system tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_stat_user_tables</code></td>
<td>Same as <code class="structname">pg_stat_all_tables</code>, except that only user
tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_stat_all_indexes</code></td>
<td>For each index in the current database,
the table and index OID, schema, table and index name,
number of index scans initiated on that index, number of
index entries returned by index scans, and number of live table rows
fetched by simple index scans using that index.
</td>
</tr>
<tr>
<td><code class="structname">pg_stat_sys_indexes</code></td>
<td>Same as <code class="structname">pg_stat_all_indexes</code>, except that only
indexes on system tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_stat_user_indexes</code></td>
<td>Same as <code class="structname">pg_stat_all_indexes</code>, except that only
indexes on user tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_statio_all_tables</code></td>
<td>For each table in the current database (including TOAST tables),
the table OID, schema and table name, number of disk
blocks read from that table, number of buffer hits, numbers of
disk blocks read and buffer hits in all indexes of that table,
numbers of disk blocks read and buffer hits from that table's
auxiliary TOAST table (if any), and numbers of disk blocks read
and buffer hits for the TOAST table's index.
</td>
</tr>
<tr>
<td><code class="structname">pg_statio_sys_tables</code></td>
<td>Same as <code class="structname">pg_statio_all_tables</code>, except that only
system tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_statio_user_tables</code></td>
<td>Same as <code class="structname">pg_statio_all_tables</code>, except that only
user tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_statio_all_indexes</code></td>
<td>For each index in the current database,
the table and index OID, schema, table and index name,
numbers of disk blocks read and buffer hits in that index.
</td>
</tr>
<tr>
<td><code class="structname">pg_statio_sys_indexes</code></td>
<td>Same as <code class="structname">pg_statio_all_indexes</code>, except that only
indexes on system tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_statio_user_indexes</code></td>
<td>Same as <code class="structname">pg_statio_all_indexes</code>, except that only
indexes on user tables are shown.</td>
</tr>
<tr>
<td><code class="structname">pg_statio_all_sequences</code></td>
<td>For each sequence object in the current database,
the sequence OID, schema and sequence name,
numbers of disk blocks read and buffer hits in that sequence.
</td>
</tr>
<tr>
<td><code class="structname">pg_statio_sys_sequences</code></td>
<td>Same as <code class="structname">pg_statio_all_sequences</code>, except that only
system sequences are shown. (Presently, no system sequences are defined,
so this view is always empty.)</td>
</tr>
<tr>
<td><code class="structname">pg_statio_user_sequences</code></td>
<td>Same as <code class="structname">pg_statio_all_sequences</code>, except that only
user sequences are shown.</td>
</tr>
</tbody>
</table></div>
</div>
<br class="table-break"><p> The per-index statistics are particularly useful to determine which
indexes are being used and how effective they are.
</p>
<p> Beginning in <span class="productname">PostgreSQL</span> 8.1, indexes can be
used either directly or via “<span class="quote">bitmap scans</span>”. In a bitmap scan
the output of several indexes can be combined via AND or OR rules;
so it is difficult to associate individual heap row fetches
with specific indexes when a bitmap scan is used. Therefore, a bitmap
scan increments the
<code class="structname">pg_stat_all_indexes</code>.<code class="structfield">idx_tup_read</code>
count(s) for the index(es) it uses, and it increments the
<code class="structname">pg_stat_all_tables</code>.<code class="structfield">idx_tup_fetch</code>
count for the table, but it does not affect
<code class="structname">pg_stat_all_indexes</code>.<code class="structfield">idx_tup_fetch</code>.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> Before <span class="productname">PostgreSQL</span> 8.1, the
<code class="structfield">idx_tup_read</code> and <code class="structfield">idx_tup_fetch</code> counts
were essentially always equal. Now they can be different even without
considering bitmap scans, because <code class="structfield">idx_tup_read</code> counts
index entries retrieved from the index while <code class="structfield">idx_tup_fetch</code>
counts live rows fetched from the table; the latter will be less if any
dead or not-yet-committed rows are fetched using the index.
</p>
</div>
<p> The <code class="structname">pg_statio_</code> views are primarily useful to
determine the effectiveness of the buffer cache. When the number
of actual disk reads is much smaller than the number of buffer
hits, then the cache is satisfying most read requests without
invoking a kernel call. However, these statistics do not give the
entire story: due to the way in which <span class="productname">PostgreSQL</span>
handles disk I/O, data that is not in the
<span class="productname">PostgreSQL</span> buffer cache may still reside in the
kernel's I/O cache, and may therefore still be fetched without
requiring a physical read. Users interested in obtaining more
detailed information on <span class="productname">PostgreSQL</span> I/O behavior are
advised to use the <span class="productname">PostgreSQL</span> statistics collector
in combination with operating system utilities that allow insight
into the kernel's handling of I/O.
</p>
<p> Other ways of looking at the statistics can be set up by writing
queries that use the same underlying statistics access functions as
these standard views do. These functions are listed in <a href="monitoring-stats.html#monitoring-stats-funcs-table" title="Table24.2.Statistics Access Functions">Table24.2, “Statistics Access Functions”</a>. The per-database access
functions take a database OID as argument to identify which
database to report on. The per-table and per-index functions take
a table or index OID. (Note that only tables and indexes in the
current database can be seen with these functions.) The
per-server-process access functions take a server process
number, which ranges from one to the number of currently active
server processes.
</p>
<div class="table">
<a name="monitoring-stats-funcs-table"></a><p class="title"><b>Table24.2.Statistics Access Functions</b></p>
<div class="table-contents"><table summary="Statistics Access Functions" border="1">
<colgroup>
<col>
<col>
<col>
</colgroup>
<thead><tr>
<th>Function</th>
<th>Return Type</th>
<th>Description</th>
</tr></thead>
<tbody>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_db_numbackends</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">integer</code></td>
<td> Number of active server processes for database
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_db_xact_commit</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Transactions committed in database
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_db_xact_rollback</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Transactions rolled back in database
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_db_blocks_fetched</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of disk block fetch requests for database
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_db_blocks_hit</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of disk block fetch requests found in cache for database
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_numscans</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of sequential scans done when argument is a table,
or number of index scans done when argument is an index
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_tuples_returned</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of rows read by sequential scans when argument is a table,
or number of index entries returned when argument is an index
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_tuples_fetched</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of table rows fetched by bitmap scans when argument is a table,
or table rows fetched by simple index scans using the index
when argument is an index
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_tuples_inserted</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of rows inserted into table
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_tuples_updated</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of rows updated in table
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_tuples_deleted</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of rows deleted from table
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_blocks_fetched</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of disk block fetch requests for table or index
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_blocks_hit</code>(<code class="type">oid</code>)</code></td>
<td><code class="type">bigint</code></td>
<td> Number of disk block requests found in cache for table or index
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_idset</code>()</code></td>
<td><code class="type">setof integer</code></td>
<td> Set of currently active server process numbers (from 1 to the
number of active server processes). See usage example in the text
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_backend_pid</code>()</code></td>
<td><code class="type">integer</code></td>
<td> Process ID of the server process attached to the current session
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_pid</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">integer</code></td>
<td> Process ID of the given server process
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_dbid</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">oid</code></td>
<td> Database ID of the given server process
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_userid</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">oid</code></td>
<td> User ID of the given server process
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_activity</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">text</code></td>
<td> Active command of the given server process (null if the
current user is not a superuser nor the same user as that of
the session being queried, or
<code class="varname">stats_command_string</code> is not on)
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_activity_start</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">timestamp with time zone</code></td>
<td> The time at which the given server process' currently
executing query was started (null if the
current user is not a superuser nor the same user as that of
the session being queried, or
<code class="varname">stats_command_string</code> is not on)
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_start</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">timestamp with time zone</code></td>
<td> The time at which the given server process was started, or
null if the current user is not a superuser nor the same user
as that of the session being queried
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_client_addr</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">inet</code></td>
<td> The IP address of the client connected to the given
server process. Null if the connection is over a Unix domain
socket. Also null if the current user is not a superuser nor
the same user as that of the session being queried
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_get_backend_client_port</code>(<code class="type">integer</code>)</code></td>
<td><code class="type">integer</code></td>
<td> The IP port number of the client connected to the given
server process. -1 if the connection is over a Unix domain
socket. Null if the current user is not a superuser nor the
same user as that of the session being queried
</td>
</tr>
<tr>
<td><code class="literal"><code class="function">pg_stat_reset</code>()</code></td>
<td><code class="type">boolean</code></td>
<td> Reset all currently collected statistics
</td>
</tr>
</tbody>
</table></div>
</div>
<br class="table-break"><div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> <code class="function">blocks_fetched</code> minus
<code class="function">blocks_hit</code> gives the number of kernel
<code class="function">read()</code> calls issued for the table, index, or
database; but the actual number of physical reads is usually
lower due to kernel-level buffering.
</p>
</div>
<p> The function <code class="function">pg_stat_get_backend_idset</code> provides
a convenient way to generate one row for each active server process. For
example, to show the <acronym class="acronym">PID</acronym>s and current queries of all server processes:
</p>
<pre class="programlisting">SELECT pg_stat_get_backend_pid(s.backendid) AS procpid,
pg_stat_get_backend_activity(s.backendid) AS current_query
FROM (SELECT pg_stat_get_backend_idset() AS backendid) AS s;</pre>
<p>
</p>
</div>
</div></body>
</html>
|