Add documentation about statistics collector and stats views & functions.
This commit is contained in:
parent
b207081056
commit
8be02853b8
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/Attic/admin.sgml,v 1.35 2001/08/26 21:17:12 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/Attic/admin.sgml,v 1.36 2001/10/16 23:57:06 tgl Exp $
|
||||
-->
|
||||
|
||||
<book id="admin">
|
||||
@ -31,6 +31,7 @@ $Header: /cvsroot/pgsql/doc/src/sgml/Attic/admin.sgml,v 1.35 2001/08/26 21:17:12
|
||||
&user-manag;
|
||||
&maintenance;
|
||||
&backup;
|
||||
&monitoring;
|
||||
&wal;
|
||||
&storage;
|
||||
&recovery;
|
||||
|
@ -1,4 +1,4 @@
|
||||
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/filelist.sgml,v 1.16 2001/09/21 18:37:05 petere Exp $ -->
|
||||
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/filelist.sgml,v 1.17 2001/10/16 23:57:06 tgl Exp $ -->
|
||||
|
||||
<!entity history SYSTEM "history.sgml">
|
||||
<!entity info SYSTEM "info.sgml">
|
||||
@ -46,6 +46,7 @@
|
||||
<!entity installw SYSTEM "install-win32.sgml">
|
||||
<!entity maintenance SYSTEM "maintenance.sgml">
|
||||
<!entity manage-ag SYSTEM "manage-ag.sgml">
|
||||
<!entity monitoring SYSTEM "monitoring.sgml">
|
||||
<!entity recovery SYSTEM "recovery.sgml">
|
||||
<!entity regress SYSTEM "regress.sgml">
|
||||
<!entity release SYSTEM "release.sgml">
|
||||
|
529
doc/src/sgml/monitoring.sgml
Normal file
529
doc/src/sgml/monitoring.sgml
Normal file
@ -0,0 +1,529 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/monitoring.sgml,v 1.1 2001/10/16 23:57:06 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="monitoring">
|
||||
<title>Monitoring Database Activity</title>
|
||||
|
||||
<para>
|
||||
A database administrator frequently wonders <quote>what is the system
|
||||
doing right now?</quote>
|
||||
This chapter discusses how to find that out.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Several tools are available for monitoring database activity and
|
||||
analyzing performance. Most of this chapter is devoted to describing
|
||||
<productname>PostgreSQL</productname>'s <firstterm>statistics collector</>,
|
||||
but one should not neglect regular Unix monitoring programs such as
|
||||
<command>ps</> and <command>top</>. Also, once one has identified a
|
||||
poorly-performing query, further investigation may be needed using
|
||||
<productname>PostgreSQL</productname>'s <command>EXPLAIN</> command.
|
||||
The <citetitle>User's Guide</citetitle> discusses <command>EXPLAIN</>
|
||||
and other methods for understanding the behavior of an individual
|
||||
query.
|
||||
</para>
|
||||
|
||||
<sect1 id="monitoring-ps">
|
||||
<title>Standard Unix Tools</Title>
|
||||
|
||||
<para>
|
||||
On most platforms, <productname>PostgreSQL</productname> modifies its
|
||||
command title as reported by <command>ps</>, so that individual server
|
||||
processes can readily be identified. A sample display is
|
||||
|
||||
<screen>
|
||||
$ ps auxww | grep ^postgres
|
||||
postgres 960 0.0 1.1 6104 1480 pts/1 SN 13:17 0:00 postmaster -i
|
||||
postgres 963 0.0 1.1 7084 1472 pts/1 SN 13:17 0:00 postgres: stats buffer process
|
||||
postgres 965 0.0 1.1 6152 1512 pts/1 SN 13:17 0:00 postgres: stats collector process
|
||||
postgres 998 0.0 2.3 6532 2992 pts/1 SN 13:18 0:00 postgres: tgl runbug [127.0.0.1] idle
|
||||
postgres 1003 0.0 2.4 6532 3128 pts/1 SN 13:19 0:00 postgres: tgl regression [local] SELECT waiting
|
||||
postgres 1016 0.1 2.4 6532 3080 pts/1 SN 13:19 0:00 postgres: tgl regression [local] idle in transaction
|
||||
</screen>
|
||||
|
||||
(The appropriate invocation of <command>ps</> varies across different
|
||||
platforms, as do the details of what is shown. This example is from a
|
||||
recent Linux system.) The first process listed here is the
|
||||
<firstterm>postmaster</>, the master server process. The command arguments
|
||||
shown for it are the same ones given when it was launched. The next two
|
||||
processes implement the statistics collector, which will be described in
|
||||
detail in the next section. (These will not be present if you have set
|
||||
the system not to start the statistics collector.) Each of the remaining
|
||||
processes is a server process handling one client connection. Each such
|
||||
process sets its command line display in the form
|
||||
|
||||
<screen>
|
||||
postgres: <replaceable>user</> <replaceable>database</> [<replaceable>host</>] <replaceable>activity</>
|
||||
</screen>
|
||||
|
||||
The user, database, and connection source host items remain the same for
|
||||
the life of the client connection, but the activity indicator changes.
|
||||
The activity may be <literal>idle</> (ie, waiting for a client command),
|
||||
<literal>idle in transaction</> (waiting for client inside a BEGIN block),
|
||||
or a command type name such as <literal>SELECT</>. Also,
|
||||
<literal>waiting</> is attached if the server is presently waiting
|
||||
on a lock held by another server process. In the above example we can infer
|
||||
that process 1003 is waiting for process 1016 to complete its transaction and
|
||||
thereby release some lock or other.
|
||||
</para>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="monitoring-stats">
|
||||
<title>Statistics Collector</Title>
|
||||
|
||||
<para>
|
||||
<productname>PostgreSQL</productname>'s <firstterm>statistics collector</>
|
||||
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 query currently being executed by other server
|
||||
processes.
|
||||
</para>
|
||||
|
||||
<sect2 id="monitoring-stats-setup">
|
||||
<title>Statistics Collection Configuration</Title>
|
||||
|
||||
<para>
|
||||
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 variables that are normally set in
|
||||
<filename>postgresql.conf</> (see <xref linkend="runtime-config"> for
|
||||
details about setting configuration variables).
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The variable <varname>STATS_START_COLLECTOR</varname> must be set to
|
||||
<literal>true</> 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The variables <varname>STATS_COMMAND_STRING</varname>,
|
||||
<varname>STATS_BLOCK_LEVEL</varname>,
|
||||
and <varname>STATS_ROW_LEVEL</varname> control how much information is
|
||||
actually sent to the collector, and thus determine how much runtime
|
||||
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 variables are
|
||||
set in <filename>postgresql.conf</> so that they apply to all server
|
||||
processes, but it is possible to turn them on or off in individual server
|
||||
processes using the <command>SET</> command. (To prevent ordinary users
|
||||
from hiding their activity from the administrator, only superusers are
|
||||
allowed to change these variables with <command>SET</>.)
|
||||
</para>
|
||||
|
||||
<caution>
|
||||
<para>
|
||||
Since the variables <varname>STATS_COMMAND_STRING</varname>,
|
||||
<varname>STATS_BLOCK_LEVEL</varname>,
|
||||
and <varname>STATS_ROW_LEVEL</varname>
|
||||
default to <literal>false</>, no statistics are actually collected
|
||||
in the default configuration! You must turn one or more of them on
|
||||
before you will get useful results from the statistical display
|
||||
functions.
|
||||
</para>
|
||||
</caution>
|
||||
|
||||
</sect2>
|
||||
|
||||
<sect2 id="monitoring-stats-views">
|
||||
<title>Viewing Collected Statistics</Title>
|
||||
|
||||
<para>
|
||||
Several predefined views are available to show the results of
|
||||
statistics collection. Alternatively, one can build custom views
|
||||
using the underlying statistics functions.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
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 access counts to the collector
|
||||
just before waiting for another client command; so a query still in
|
||||
progress does not affect the displayed totals. Also, the collector itself
|
||||
emits new totals at most once per PGSTAT_STAT_INTERVAL (500 milliseconds
|
||||
by default). So the displayed totals lag behind actual activity.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Another important point is that when a server process is asked to display
|
||||
any of these statistics, it first fetches the most recent totals emitted by
|
||||
the collector process. It 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.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title>Standard Statistics Views</title>
|
||||
|
||||
<tgroup cols="2">
|
||||
<thead>
|
||||
<row>
|
||||
<entry>View Name</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structname>pg_stat_activity</></entry>
|
||||
<entry>One row per server process, showing process PID, database,
|
||||
user, and current query. The current query column is only available
|
||||
to superusers; for others it reads as NULL. (Note that because of
|
||||
the collector's reporting delay, current query will only be up-to-date
|
||||
for long-running queries.)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_database</></entry>
|
||||
<entry>One row per database, showing number of active backends,
|
||||
total transactions committed and total rolled back in that database,
|
||||
total disk blocks read, and total number of buffer hits (ie, block
|
||||
read requests avoided by finding the block already in buffer cache).
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_all_tables</></entry>
|
||||
<entry>For each table in the current database, total numbers of
|
||||
sequential and index scans, total numbers of tuples returned by
|
||||
each type of scan, and totals of tuple insertions, updates,
|
||||
and deletes.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_sys_tables</></entry>
|
||||
<entry>Same as pg_stat_all_tables, except that only system tables
|
||||
are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_user_tables</></entry>
|
||||
<entry>Same as pg_stat_all_tables, except that only user tables
|
||||
are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_all_indexes</></entry>
|
||||
<entry>For each index in the current database, the total number
|
||||
of index scans that have used that index, the number of index tuples
|
||||
read, and the number of successfully fetched heap tuples (this may
|
||||
be less when there are index entries pointing to expired heap tuples).
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_sys_indexes</></entry>
|
||||
<entry>Same as pg_stat_all_indexes, except that only indexes on
|
||||
system tables are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_stat_user_indexes</></entry>
|
||||
<entry>Same as pg_stat_all_indexes, except that only indexes on
|
||||
user tables are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_all_tables</></entry>
|
||||
<entry>For each table in the current database, the total number of disk
|
||||
blocks read from that table, the number of buffer hits, the numbers of
|
||||
disk blocks read and buffer hits in all the indexes of that table,
|
||||
the numbers of disk blocks read and buffer hits from the table's
|
||||
auxiliary TOAST table (if any), and the numbers of disk blocks read
|
||||
and buffer hits for the TOAST table's index.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_sys_tables</></entry>
|
||||
<entry>Same as pg_statio_all_tables, except that only system tables
|
||||
are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_user_tables</></entry>
|
||||
<entry>Same as pg_statio_all_tables, except that only user tables
|
||||
are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_all_indexes</></entry>
|
||||
<entry>For each index in the current database, the numbers of
|
||||
disk blocks read and buffer hits in that index.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_sys_indexes</></entry>
|
||||
<entry>Same as pg_statio_all_indexes, except that only indexes on
|
||||
system tables are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_user_indexes</></entry>
|
||||
<entry>Same as pg_statio_all_indexes, except that only indexes on
|
||||
user tables are shown.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_all_sequences</></entry>
|
||||
<entry>For each sequence object in the current database, the numbers
|
||||
of disk blocks read and buffer hits in that sequence.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_sys_sequences</></entry>
|
||||
<entry>Same as pg_statio_all_sequences, except that only system
|
||||
sequences are shown. (Presently, no system sequences are defined,
|
||||
so this view is always empty.)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structname>pg_statio_user_sequences</></entry>
|
||||
<entry>Same as pg_statio_all_sequences, except that only user
|
||||
sequences are shown.</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The per-index statistics are particularly useful to determine which
|
||||
indexes are being used and how effective they are.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <structname>pg_statio_</> 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
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. The per-database access functions accept a database OID to
|
||||
identify which database to report on. The per-table and per-index
|
||||
functions accept a table or index OID (note that only tables and indexes
|
||||
in the current
|
||||
database can be seen with these functions). The per-backend access
|
||||
functions accept a backend ID number, which ranges from one to the number
|
||||
of currently active backends.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title>Statistics Access Functions</title>
|
||||
|
||||
<tgroup cols="3">
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Function</entry>
|
||||
<entry>Return Type</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><function>pg_stat_get_db_numbackends</function>(<type>oid</type>)</entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry>
|
||||
Number of active backends in database
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_db_xact_commit</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Transactions committed in database
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_db_xact_rollback</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Transactions rolled back in database
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_db_blocks_fetched</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of disk block fetch requests for database
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_db_blocks_hit</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of disk block requests found in cache for database
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_numscans</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of sequential scans done when argument is a table,
|
||||
or number of index scans done when argument is an index
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_tuples_returned</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of tuples read by sequential scans when argument is a table,
|
||||
or number of index tuples read when argument is an index
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_tuples_fetched</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of valid (unexpired) table tuples fetched by sequential scans
|
||||
when argument is a table, or fetched by index scans using this index
|
||||
when argument is an index
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_tuples_inserted</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of tuples inserted into table
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_tuples_updated</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of tuples updated in table
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_tuples_deleted</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of tuples deleted from table
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_blocks_fetched</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of disk block fetch requests for table or index
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_blocks_hit</function>(<type>oid</type>)</entry>
|
||||
<entry><type>bigint</type></entry>
|
||||
<entry>
|
||||
Number of disk block requests found in cache for table or index
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_backend_idset</function>()</entry>
|
||||
<entry><type>set of integer</type></entry>
|
||||
<entry>
|
||||
Set of currently active backend IDs (from 1 to N where N is the
|
||||
number of active backends). See usage example below.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_backend_pid</function>(<type>integer</type>)</entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry>
|
||||
PID of backend process
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_backend_dbid</function>(<type>integer</type>)</entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry>
|
||||
Database ID of backend process
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_backend_userid</function>(<type>integer</type>)</entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry>
|
||||
User ID of backend process
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><function>pg_stat_get_backend_activity</function>(<type>integer</type>)</entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>
|
||||
Current query of backend process (NULL if caller is not superuser)
|
||||
</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
Note: blocks_fetched minus blocks_hit gives the number of kernel read()
|
||||
calls issued for the table, index, or database; but the actual number of
|
||||
physical reads is usually lower due to kernel-level buffering.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The function <function>pg_stat_get_backend_idset</function> provides
|
||||
a convenient way to generate one row for each active backend. For
|
||||
example, to show the PIDs and current queries of all backends:
|
||||
|
||||
<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;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
</sect2>
|
||||
</sect1>
|
||||
</chapter>
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
Local variables:
|
||||
mode:sgml
|
||||
sgml-omittag:nil
|
||||
sgml-shorttag:t
|
||||
sgml-minimize-attributes:nil
|
||||
sgml-always-quote-attributes:t
|
||||
sgml-indent-step:1
|
||||
sgml-indent-data:t
|
||||
sgml-parent-document:nil
|
||||
sgml-default-dtd-file:"./reference.ced"
|
||||
sgml-exposed-tags:nil
|
||||
sgml-local-catalogs:("/usr/lib/sgml/catalog")
|
||||
sgml-local-ecat-files:nil
|
||||
End:
|
||||
-->
|
Loading…
x
Reference in New Issue
Block a user