From: Tom Lane Date: Tue, 16 Oct 2001 23:57:06 +0000 (+0000) Subject: Add documentation about statistics collector and stats views & functions. X-Git-Tag: REL7_2_BETA1~75 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=8be02853b899b5aefc4bee1b1dd489705df3e082;p=postgresql Add documentation about statistics collector and stats views & functions. --- diff --git a/doc/src/sgml/admin.sgml b/doc/src/sgml/admin.sgml index 32c0983b17..da8edaf011 100644 --- a/doc/src/sgml/admin.sgml +++ b/doc/src/sgml/admin.sgml @@ -1,5 +1,5 @@ @@ -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; diff --git a/doc/src/sgml/filelist.sgml b/doc/src/sgml/filelist.sgml index 6761d59f28..d5ac242972 100644 --- a/doc/src/sgml/filelist.sgml +++ b/doc/src/sgml/filelist.sgml @@ -1,4 +1,4 @@ - + @@ -46,6 +46,7 @@ + diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml new file mode 100644 index 0000000000..6d17855588 --- /dev/null +++ b/doc/src/sgml/monitoring.sgml @@ -0,0 +1,529 @@ + + + + Monitoring Database Activity + + + A database administrator frequently wonders what is the system + doing right now? + This chapter discusses how to find that out. + + + + Several tools are available for monitoring database activity and + analyzing performance. Most of this chapter is devoted to describing + PostgreSQL's statistics collector, + but one should not neglect regular Unix monitoring programs such as + ps and top. Also, once one has identified a + poorly-performing query, further investigation may be needed using + PostgreSQL's EXPLAIN command. + The User's Guide discusses EXPLAIN + and other methods for understanding the behavior of an individual + query. + + + + Standard Unix Tools + + + On most platforms, PostgreSQL modifies its + command title as reported by ps, so that individual server + processes can readily be identified. A sample display is + + +$ 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 + + + (The appropriate invocation of 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 + 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 + + +postgres: user database [host] activity + + + 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 idle (ie, waiting for a client command), + idle in transaction (waiting for client inside a BEGIN block), + or a command type name such as SELECT. Also, + 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. + + + + + Statistics Collector + + + PostgreSQL's 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. + + + + Statistics Collection Configuration + + + 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 + postgresql.conf (see for + details about setting configuration variables). + + + + The variable STATS_START_COLLECTOR must be set to + 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. + + + + The variables STATS_COMMAND_STRING, + STATS_BLOCK_LEVEL, + and STATS_ROW_LEVEL 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 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 SET command. (To prevent ordinary users + from hiding their activity from the administrator, only superusers are + allowed to change these variables with SET.) + + + + + Since the variables STATS_COMMAND_STRING, + STATS_BLOCK_LEVEL, + and STATS_ROW_LEVEL + default to 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. + + + + + + + Viewing Collected Statistics + + + Several predefined views are available to show the results of + statistics collection. Alternatively, one can build custom views + using the underlying statistics functions. + + + + 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. + + + + 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. + + + + Standard Statistics Views + + + + + View Name + Description + + + + + + pg_stat_activity + 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.) + + + + pg_stat_database + 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). + + + + + pg_stat_all_tables + 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. + + + + pg_stat_sys_tables + Same as pg_stat_all_tables, except that only system tables + are shown. + + + + pg_stat_user_tables + Same as pg_stat_all_tables, except that only user tables + are shown. + + + + pg_stat_all_indexes + 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). + + + + + pg_stat_sys_indexes + Same as pg_stat_all_indexes, except that only indexes on + system tables are shown. + + + + pg_stat_user_indexes + Same as pg_stat_all_indexes, except that only indexes on + user tables are shown. + + + + pg_statio_all_tables + 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. + + + + + pg_statio_sys_tables + Same as pg_statio_all_tables, except that only system tables + are shown. + + + + pg_statio_user_tables + Same as pg_statio_all_tables, except that only user tables + are shown. + + + + pg_statio_all_indexes + For each index in the current database, the numbers of + disk blocks read and buffer hits in that index. + + + + + pg_statio_sys_indexes + Same as pg_statio_all_indexes, except that only indexes on + system tables are shown. + + + + pg_statio_user_indexes + Same as pg_statio_all_indexes, except that only indexes on + user tables are shown. + + + + pg_statio_all_sequences + For each sequence object in the current database, the numbers + of disk blocks read and buffer hits in that sequence. + + + + + pg_statio_sys_sequences + 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.) + + + + pg_statio_user_sequences + Same as pg_statio_all_sequences, except that only user + sequences are shown. + + + +
+ + + The per-index statistics are particularly useful to determine which + indexes are being used and how effective they are. + + + + The 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. + + + + 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. + + + + Statistics Access Functions + + + + + Function + Return Type + Description + + + + + + pg_stat_get_db_numbackends(oid) + integer + + Number of active backends in database + + + + + pg_stat_get_db_xact_commit(oid) + bigint + + Transactions committed in database + + + + + pg_stat_get_db_xact_rollback(oid) + bigint + + Transactions rolled back in database + + + + + pg_stat_get_db_blocks_fetched(oid) + bigint + + Number of disk block fetch requests for database + + + + + pg_stat_get_db_blocks_hit(oid) + bigint + + Number of disk block requests found in cache for database + + + + + pg_stat_get_numscans(oid) + bigint + + Number of sequential scans done when argument is a table, + or number of index scans done when argument is an index + + + + + pg_stat_get_tuples_returned(oid) + bigint + + Number of tuples read by sequential scans when argument is a table, + or number of index tuples read when argument is an index + + + + + pg_stat_get_tuples_fetched(oid) + bigint + + 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 + + + + + pg_stat_get_tuples_inserted(oid) + bigint + + Number of tuples inserted into table + + + + + pg_stat_get_tuples_updated(oid) + bigint + + Number of tuples updated in table + + + + + pg_stat_get_tuples_deleted(oid) + bigint + + Number of tuples deleted from table + + + + + pg_stat_get_blocks_fetched(oid) + bigint + + Number of disk block fetch requests for table or index + + + + + pg_stat_get_blocks_hit(oid) + bigint + + Number of disk block requests found in cache for table or index + + + + + pg_stat_get_backend_idset() + set of integer + + Set of currently active backend IDs (from 1 to N where N is the + number of active backends). See usage example below. + + + + + pg_stat_get_backend_pid(integer) + integer + + PID of backend process + + + + + pg_stat_get_backend_dbid(integer) + oid + + Database ID of backend process + + + + + pg_stat_get_backend_userid(integer) + oid + + User ID of backend process + + + + + pg_stat_get_backend_activity(integer) + text + + Current query of backend process (NULL if caller is not superuser) + + + + +
+ + + 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. + + + + The function pg_stat_get_backend_idset provides + a convenient way to generate one row for each active backend. For + example, to show the PIDs and current queries of all backends: + + +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; + + + +
+
+
+ +