mirror of
				https://github.com/postgres/postgres.git
				synced 2025-10-29 22:49:41 +03:00 
			
		
		
		
	generated by bitmap index scans. Along the way, simplify and speed up the code for counting sequential and index scans; it was both confusing and inefficient to be taking care of that in the per-tuple loops, IMHO. initdb forced because of internal changes in pg_stat view definitions.
		
			
				
	
	
		
			741 lines
		
	
	
		
			28 KiB
		
	
	
	
		
			Plaintext
		
	
	
	
	
	
			
		
		
	
	
			741 lines
		
	
	
		
			28 KiB
		
	
	
	
		
			Plaintext
		
	
	
	
	
	
| <!--
 | |
| $PostgreSQL: pgsql/doc/src/sgml/monitoring.sgml,v 1.29 2005/10/06 02:29:06 tgl Exp $
 | |
| -->
 | |
| 
 | |
| <chapter id="monitoring">
 | |
|  <title>Monitoring Database Activity</title>
 | |
| 
 | |
|  <indexterm zone="monitoring">
 | |
|   <primary>monitoring</primary>
 | |
|   <secondary>database activity</secondary>
 | |
|  </indexterm>
 | |
| 
 | |
|  <indexterm zone="monitoring">
 | |
|   <primary>database activity</primary>
 | |
|   <secondary>monitoring</secondary>
 | |
|  </indexterm>
 | |
| 
 | |
|  <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 statistics collector,
 | |
|    but one should not neglect regular Unix monitoring programs such as
 | |
|    <command>ps</>, <command>top</>, <command>iostat</>, and <command>vmstat</>.
 | |
|    Also, once one has identified a
 | |
|    poorly-performing query, further investigation may be needed using
 | |
|    <productname>PostgreSQL</productname>'s <xref linkend="sql-explain"
 | |
|    endterm="sql-explain-title"> command.
 | |
|    <xref linkend="using-explain"> discusses <command>EXPLAIN</>
 | |
|    and other methods for understanding the behavior of an individual
 | |
|    query.
 | |
|   </para>
 | |
| 
 | |
|  <sect1 id="monitoring-ps">
 | |
|   <title>Standard Unix Tools</Title>
 | |
| 
 | |
|   <indexterm zone="monitoring-ps">
 | |
|    <primary>ps</primary>
 | |
|    <secondary>to monitor activity</secondary>
 | |
|   </indexterm>
 | |
| 
 | |
|   <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
 | |
|    <application>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</> (i.e., waiting for a client command),
 | |
|   <literal>idle in transaction</> (waiting for client inside a <command>BEGIN</> block),
 | |
|   or a command type name such as <literal>SELECT</>.  Also,
 | |
|   <literal>waiting</> is attached if the server process 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>
 | |
| 
 | |
|   <tip>
 | |
|   <para>
 | |
|   <productname>Solaris</productname> requires special handling. You must
 | |
|   use <command>/usr/ucb/ps</command>, rather than
 | |
|   <command>/bin/ps</command>. You also must use two <option>w</option>
 | |
|   flags, not just one. In addition, your original invocation of the
 | |
|   <command>postmaster</command> command must have a shorter
 | |
|   <command>ps</command> status display than that provided by each
 | |
|   server process.  If you fail to do all three things, the <command>ps</>
 | |
|   output for each server process will be the original <command>postmaster</>
 | |
|   command line.
 | |
|   </para>
 | |
|   </tip>
 | |
|  </sect1>
 | |
| 
 | |
|  <sect1 id="monitoring-stats">
 | |
|   <title>The Statistics Collector</Title>
 | |
| 
 | |
|   <indexterm zone="monitoring-stats">
 | |
|    <primary>statistics</primary>
 | |
|   </indexterm>
 | |
| 
 | |
|   <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 command 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 parameters that are normally set in
 | |
|    <filename>postgresql.conf</>.  (See <xref linkend="runtime-config"> for
 | |
|    details about setting configuration parameters.)
 | |
|   </para>
 | |
| 
 | |
|   <para>
 | |
|    The parameter <xref linkend="guc-stats-start-collector"> 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 parameters <xref linkend="guc-stats-command-string">,
 | |
|    <xref linkend="guc-stats-block-level">, and <xref
 | |
|    linkend="guc-stats-row-level"> 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 <filename>postgresql.conf</>
 | |
|    so that they apply to all server processes, but it is possible to
 | |
|    turn them on or off in individual sessions using the <xref
 | |
|    linkend="sql-set" endterm="sql-set-title"> command.  (To prevent
 | |
|    ordinary users from hiding their activity from the administrator,
 | |
|    only superusers are allowed to change these parameters with
 | |
|    <command>SET</>.)
 | |
|   </para>
 | |
| 
 | |
|    <note>
 | |
|     <para>
 | |
|      Since the parameters <varname>stats_command_string</varname>,
 | |
|      <varname>stats_block_level</varname>, and
 | |
|      <varname>stats_row_level</varname> default to <literal>false</>,
 | |
|      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.
 | |
|     </para>
 | |
|    </note>
 | |
| 
 | |
|  </sect2>
 | |
| 
 | |
|  <sect2 id="monitoring-stats-views">
 | |
|   <title>Viewing Collected Statistics</Title>
 | |
| 
 | |
|   <para>
 | |
|    Several predefined views, listed in <xref
 | |
|    linkend="monitoring-stats-views-table">, 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 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 <varname>PGSTAT_STAT_INTERVAL</varname>
 | |
|    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 <varname>PGSTAT_STAT_INTERVAL</varname> delay before it becomes
 | |
|    visible.
 | |
|   </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 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.
 | |
|   </para>
 | |
| 
 | |
|   <table id="monitoring-stats-views-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 database OID, database name,
 | |
|       process <acronym>ID</>, 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 <varname>stats_command_string</varname> 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.)</entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_stat_database</></entry>
 | |
|       <entry>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).
 | |
|      </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_stat_all_tables</></entry>
 | |
|       <entry>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.</entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_stat_sys_tables</></entry>
 | |
|       <entry>Same as <structname>pg_stat_all_tables</>, except that only
 | |
|       system tables are shown.</entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_stat_user_tables</></entry>
 | |
|       <entry>Same as <structname>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 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.
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_stat_sys_indexes</></entry>
 | |
|       <entry>Same as <structname>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 <structname>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 (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.
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_statio_sys_tables</></entry>
 | |
|       <entry>Same as <structname>pg_statio_all_tables</>, except that only
 | |
|       system tables are shown.</entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_statio_user_tables</></entry>
 | |
|       <entry>Same as <structname>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 table and index OID, schema, table and index name,
 | |
|       numbers of disk blocks read and buffer hits in that index.
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_statio_sys_indexes</></entry>
 | |
|       <entry>Same as <structname>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 <structname>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 sequence OID, schema and sequence name,
 | |
|       numbers of disk blocks read and buffer hits in that sequence.
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><structname>pg_statio_sys_sequences</></entry>
 | |
|       <entry>Same as <structname>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 <structname>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>
 | |
|    Beginning in <productname>PostgreSQL</productname> 8.1, indexes can be
 | |
|    used either directly or via <quote>bitmap scans</>.  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
 | |
|    <structname>pg_stat_all_indexes</>.<structfield>idx_tup_read</>
 | |
|    count(s) for the index(es) it uses, and it increments the
 | |
|    <structname>pg_stat_all_tables</>.<structfield>idx_tup_fetch</>
 | |
|    count for the table, but it does not affect
 | |
|    <structname>pg_stat_all_indexes</>.<structfield>idx_tup_fetch</>.
 | |
|   </para>
 | |
| 
 | |
|   <note>
 | |
|    <para>
 | |
|     Before <productname>PostgreSQL</productname> 8.1, the
 | |
|     <structfield>idx_tup_read</> and <structfield>idx_tup_fetch</> counts
 | |
|     were essentially always equal.  Now they can be different even without
 | |
|     considering bitmap scans, because <structfield>idx_tup_read</> counts
 | |
|     index entries retrieved from the index while <structfield>idx_tup_fetch</>
 | |
|     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.
 | |
|    </para>
 | |
|   </note>
 | |
| 
 | |
|   <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. However, these statistics do not give the
 | |
|    entire story: due to the way in which <productname>PostgreSQL</>
 | |
|    handles disk I/O, data that is not in the
 | |
|    <productname>PostgreSQL</> 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 <productname>PostgreSQL</> I/O behavior are
 | |
|    advised to use the <productname>PostgreSQL</> statistics collector
 | |
|    in combination with operating system utilities that allow insight
 | |
|    into the kernel's handling of I/O.
 | |
|   </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.  These functions are listed in <xref
 | |
|    linkend="monitoring-stats-funcs-table">.  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.
 | |
|   </para>
 | |
| 
 | |
|   <table id="monitoring-stats-funcs-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><literal><function>pg_stat_get_db_numbackends</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>integer</type></entry>
 | |
|       <entry>
 | |
|        Number of active server processes for database
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_db_xact_commit</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Transactions committed in database
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_db_xact_rollback</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Transactions rolled back in database
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_db_blocks_fetched</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of disk block fetch requests for database
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_db_blocks_hit</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of disk block fetch requests found in cache for database
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_numscans</function>(<type>oid</type>)</literal></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><literal><function>pg_stat_get_tuples_returned</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of rows read by sequential scans when argument is a table,
 | |
|        or number of index entries returned when argument is an index
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_tuples_fetched</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_tuples_inserted</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of rows inserted into table
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_tuples_updated</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of rows updated in table
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_tuples_deleted</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of rows deleted from table
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_blocks_fetched</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of disk block fetch requests for table or index
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_blocks_hit</function>(<type>oid</type>)</literal></entry>
 | |
|       <entry><type>bigint</type></entry>
 | |
|       <entry>
 | |
|        Number of disk block requests found in cache for table or index
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_idset</function>()</literal></entry>
 | |
|       <entry><type>setof integer</type></entry>
 | |
|       <entry>
 | |
|        Set of currently active server process numbers (from 1 to the
 | |
|        number of active server processes).  See usage example in the text
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_backend_pid</function>()</literal></entry>
 | |
|       <entry><type>integer</type></entry>
 | |
|       <entry>
 | |
|        Process ID of the server process attached to the current session
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_pid</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>integer</type></entry>
 | |
|       <entry>
 | |
|        Process ID of the given server process
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_dbid</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>oid</type></entry>
 | |
|       <entry>
 | |
|        Database ID of the given server process
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_userid</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>oid</type></entry>
 | |
|       <entry>
 | |
|        User ID of the given server process
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_activity</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>text</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|        <varname>stats_command_string</varname> is not on)
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_activity_start</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>timestamp with time zone</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|        <varname>stats_command_string</varname> is not on)
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_start</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>timestamp with time zone</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_client_addr</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>inet</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_get_backend_client_port</function>(<type>integer</type>)</literal></entry>
 | |
|       <entry><type>integer</type></entry>
 | |
|       <entry>
 | |
|        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
 | |
|       </entry>
 | |
|      </row>
 | |
| 
 | |
|      <row>
 | |
|       <entry><literal><function>pg_stat_reset</function>()</literal></entry>
 | |
|       <entry><type>boolean</type></entry>
 | |
|       <entry>
 | |
|        Reset all currently collected statistics
 | |
|       </entry>
 | |
|      </row>
 | |
|     </tbody>
 | |
|    </tgroup>
 | |
|   </table>
 | |
| 
 | |
|    <note>
 | |
|     <para>
 | |
|      <function>blocks_fetched</function> minus
 | |
|      <function>blocks_hit</function> gives the number of kernel
 | |
|      <function>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>
 | |
|    </note>
 | |
| 
 | |
|   <para>
 | |
|    The function <function>pg_stat_get_backend_idset</function> provides
 | |
|    a convenient way to generate one row for each active server process.  For
 | |
|    example, to show the <acronym>PID</>s and current queries of all server processes:
 | |
| 
 | |
| <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>
 | |
| 
 | |
|  <sect1 id="monitoring-locks">
 | |
|   <title>Viewing Locks</title>
 | |
| 
 | |
|   <indexterm zone="monitoring-locks">
 | |
|    <primary>lock</primary>
 | |
|    <secondary>monitoring</secondary>
 | |
|   </indexterm>
 | |
| 
 | |
|   <para>
 | |
|    Another useful tool for monitoring database activity is the
 | |
|    <structname>pg_locks</structname> system table.  It allows the
 | |
|    database administrator to view information about the outstanding
 | |
|    locks in the lock manager. For example, this capability can be used
 | |
|    to:
 | |
| 
 | |
|    <itemizedlist>
 | |
|     <listitem>
 | |
|      <para>
 | |
|       View all the locks currently outstanding, all the locks on
 | |
|       relations in a particular database, all the locks on a
 | |
|       particular relation, or all the locks held by a particular
 | |
|       <productname>PostgreSQL</productname> session.
 | |
|      </para>
 | |
|     </listitem>
 | |
| 
 | |
|     <listitem>
 | |
|      <para>
 | |
|       Determine the relation in the current database with the most
 | |
|       ungranted locks (which might be a source of contention among
 | |
|       database clients).
 | |
|      </para>
 | |
|     </listitem>
 | |
| 
 | |
|     <listitem>
 | |
|      <para>
 | |
|       Determine the effect of lock contention on overall database
 | |
|       performance, as well as the extent to which contention varies
 | |
|       with overall database traffic.
 | |
|      </para>
 | |
|     </listitem>
 | |
|    </itemizedlist>
 | |
| 
 | |
|    Details of the <structname>pg_locks</structname> view appear in
 | |
|    <xref linkend="view-pg-locks">.
 | |
|    For more information on locking and managing concurrency with
 | |
|    <productname>PostgreSQL</productname>, refer to <xref linkend="mvcc">.
 | |
|   </para>
 | |
|  </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:
 | |
| -->
 |