26.2. The 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 tracks total numbers of rows in each table, and the last vacuum and analyze times for each table. It can also count calls to user-defined functions and the total time spent in each one.

PostgreSQL also supports determining the exact command currently being executed by other server processes. This is an independent facility that does not depend on the collector process.

26.2.1. 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 parameters that are normally set in postgresql.conf. (See Chapter 18 for details about setting configuration parameters.)

The parameter track_counts controls whether statistics are collected about table and index accesses.

The parameter track_functions enables tracking of usage of user-defined functions.

The parameter track_activities enables monitoring of the current command being executed by any server process.

Normally these parameters 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 sessions using the SET command. (To prevent ordinary users from hiding their activity from the administrator, only superusers are allowed to change these parameters with SET.)

The statistics collector communicates with the backends needing information (including autovacuum) through temporary files. These files are stored in the pg_stat_tmp subdirectory. When the postmaster shuts down, a permanent copy of the statistics data is stored in the global subdirectory. For increased performance, the parameter stats_temp_directory can be pointed at a RAM based filesystem, decreasing physical I/O requirements.

26.2.2. Viewing Collected Statistics

Several predefined views, listed in Table 26-1, 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 statistical 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 PGSTAT_STAT_INTERVAL milliseconds (500 unless altered while building the server). So the displayed information lags behind actual activity. However, current-query information collected by track_activities is always up-to-date.

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. Similarly, information about the current queries of all processes is collected when any such information is first requested within a transaction, and the same information will be displayed throughout the 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. Alternatively, you can invoke pg_stat_clear_snapshot(), which will discard the current transaction's statistics snapshot (if any). The next use of statistical information will cause a new snapshot to be fetched.

Table 26-1. Standard Statistics Views

View NameDescription
pg_stat_activityOne row per server process, showing database OID, database name, process ID, user OID, user name, current query, query's waiting status, time at which the current transaction and 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 available unless the parameter track_activities has been turned off. Furthermore, these columns are only visible if the user examining the view is a superuser or the same as the user owning the process being reported on.
pg_stat_bgwriterOne row only, showing cluster-wide statistics from the background writer: number of scheduled checkpoints, requested checkpoints, buffers written by checkpoints and cleaning scans, and the number of times the background writer stopped a cleaning scan because it had written too many buffers. Also includes statistics about the shared buffer pool, including buffers written by backends (that is, not by the background writer) and total buffers allocated.
pg_stat_databaseOne 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, total buffer hits (i.e., block read requests avoided by finding the block already in buffer cache), number of rows returned, fetched, inserted, updated and deleted.
pg_stat_all_tablesFor 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, numbers of row insertions, updates, and deletions, number of row updates that were HOT (i.e., no separate index update), numbers of live and dead rows, the last time the table was vacuumed manually, the last time it was vacuumed by the autovacuum daemon, the last time it was analyzed manually, and the last time it was analyzed by the autovacuum daemon.
pg_stat_sys_tablesSame as pg_stat_all_tables, except that only system tables are shown.
pg_stat_user_tablesSame as pg_stat_all_tables, except that only user tables are shown.
pg_stat_all_indexesFor 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.
pg_stat_sys_indexesSame as pg_stat_all_indexes, except that only indexes on system tables are shown.
pg_stat_user_indexesSame as pg_stat_all_indexes, except that only indexes on user tables are shown.
pg_statio_all_tablesFor 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.
pg_statio_sys_tablesSame as pg_statio_all_tables, except that only system tables are shown.
pg_statio_user_tablesSame as pg_statio_all_tables, except that only user tables are shown.
pg_statio_all_indexesFor 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.
pg_statio_sys_indexesSame as pg_statio_all_indexes, except that only indexes on system tables are shown.
pg_statio_user_indexesSame as pg_statio_all_indexes, except that only indexes on user tables are shown.
pg_statio_all_sequencesFor 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.
pg_statio_sys_sequencesSame 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_sequencesSame as pg_statio_all_sequences, except that only user sequences are shown.
pg_stat_user_functionsFor all tracked functions, function OID, schema, name, number of calls, total time, and self time. Self time is the amount of time spent in the function itself, total time includes the time spent in functions it called. Time values are in milliseconds.

The per-index statistics are particularly useful to determine which indexes are being used and how effective they are.

Beginning in PostgreSQL 8.1, indexes can be used either directly or via "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 pg_stat_all_indexes.idx_tup_read count(s) for the index(es) it uses, and it increments the pg_stat_all_tables.idx_tup_fetch count for the table, but it does not affect pg_stat_all_indexes.idx_tup_fetch.

Note: Before PostgreSQL 8.1, the idx_tup_read and idx_tup_fetch counts were essentially always equal. Now they can be different even without considering bitmap scans, because idx_tup_read counts index entries retrieved from the index while 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.

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. However, these statistics do not give the entire story: due to the way in which PostgreSQL handles disk I/O, data that is not in the PostgreSQL buffer cache might still reside in the kernel's I/O cache, and might therefore still be fetched without requiring a physical read. Users interested in obtaining more detailed information on PostgreSQL I/O behavior are advised to use the PostgreSQL statistics collector in combination with operating system utilities that allow insight into the kernel's handling of I/O.

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 Table 26-2. 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. The functions for function-call statistics take a function OID. (Note that only tables, indexes, and functions 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.

Table 26-2. Statistics Access Functions

FunctionReturn TypeDescription
pg_stat_get_db_numbackends(oid)integer Number of active server processes for 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 fetch requests found in cache for database
pg_stat_get_db_tuples_returned(oid)bigint Number of tuples returned for database
pg_stat_get_db_tuples_fetched(oid)bigint Number of tuples fetched for database
pg_stat_get_db_tuples_inserted(oid)bigint Number of tuples inserted in database
pg_stat_get_db_tuples_updated(oid)bigint Number of tuples updated in database
pg_stat_get_db_tuples_deleted(oid)bigint Number of tuples deleted in 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 rows read by sequential scans when argument is a table, or number of index entries returned when argument is an index
pg_stat_get_tuples_fetched(oid)bigint 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
pg_stat_get_tuples_inserted(oid)bigint Number of rows inserted into table
pg_stat_get_tuples_updated(oid)bigint Number of rows updated in table (includes HOT updates)
pg_stat_get_tuples_deleted(oid)bigint Number of rows deleted from table
pg_stat_get_tuples_hot_updated(oid)bigint Number of rows HOT-updated in table
pg_stat_get_live_tuples(oid)bigint Number of live rows in table
pg_stat_get_dead_tuples(oid)bigint Number of dead rows in 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_last_vacuum_time(oid)timestamptz Time of the last vacuum initiated by the user on this table
pg_stat_get_last_autovacuum_time(oid)timestamptz Time of the last vacuum initiated by the autovacuum daemon on this table
pg_stat_get_last_analyze_time(oid)timestamptz Time of the last analyze initiated by the user on this table
pg_stat_get_last_autoanalyze_time(oid)timestamptz Time of the last analyze initiated by the autovacuum daemon on this table
pg_backend_pid()integer Process ID of the server process attached to the current session
pg_stat_get_activity(integer)setof record Returns a record of information about the backend with the specified pid, or one record for each active backend in the system if NULL is specified. The fields returned are the same as in the pg_stat_activity view
pg_stat_get_function_calls(oid)bigint Number of times the function has been called.
pg_stat_get_function_time(oid)bigint Total wall clock time spent in the function, in microseconds. Includes the time spent in functions called by this one.
pg_stat_get_function_self_time(oid)bigint Time spent in only this function. Time spent in called functions is excluded.
pg_stat_get_backend_idset()setof integer Set of currently active server process numbers (from 1 to the number of active server processes). See usage example in the text
pg_stat_get_backend_pid(integer)integer Process ID of the given server process
pg_stat_get_backend_dbid(integer)oid Database ID of the given server process
pg_stat_get_backend_userid(integer)oid User ID of the given server process
pg_stat_get_backend_activity(integer)text Active command of the given server process, but only if the current user is a superuser or the same user as that of the session being queried (and track_activities is on)
pg_stat_get_backend_waiting(integer)boolean True if the given server process is waiting for a lock, but only if the current user is a superuser or the same user as that of the session being queried (and track_activities is on)
pg_stat_get_backend_activity_start(integer)timestamp with time zone The time at which the given server process' currently executing query was started, but only if the current user is a superuser or the same user as that of the session being queried (and track_activities is on)
pg_stat_get_backend_xact_start(integer)timestamp with time zone The time at which the given server process' currently executing transaction was started, but only if the current user is a superuser or the same user as that of the session being queried (and track_activities is on)
pg_stat_get_backend_start(integer)timestamp with time zone 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
pg_stat_get_backend_client_addr(integer)inet 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
pg_stat_get_backend_client_port(integer)integer The TCP 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
pg_stat_get_bgwriter_timed_checkpoints()bigint The number of times the background writer has started timed checkpoints (because the checkpoint_timeout time has expired)
pg_stat_get_bgwriter_requested_checkpoints()bigint The number of times the background writer has started checkpoints based on requests from backends because the checkpoint_segments has been exceeded or because the CHECKPOINT command has been issued
pg_stat_get_bgwriter_buf_written_checkpoints()bigint The number of buffers written by the background writer during checkpoints
pg_stat_get_bgwriter_buf_written_clean()bigint The number of buffers written by the background writer for routine cleaning of dirty pages
pg_stat_get_bgwriter_maxwritten_clean()bigint The number of times the background writer has stopped its cleaning scan because it has written more buffers than specified in the bgwriter_lru_maxpages parameter
pg_stat_get_buf_written_backend()bigint The number of buffers written by backends because they needed to allocate a new buffer
pg_stat_get_buf_alloc()bigint The total number of buffer allocations
pg_stat_clear_snapshot()void Discard the current statistics snapshot
pg_stat_reset()void Reset all statistics counters for the current database to zero (requires superuser privileges)

Note: pg_stat_get_blocks_fetched minus pg_stat_get_blocks_hit gives the number of kernel read() calls issued for the table, index, or database; the number of actual physical reads is usually lower due to kernel-level buffering. The *_blks_read statistics columns use this subtraction, i.e., fetched minus hit.

All functions to access information about backends are indexed by backend id number, except pg_stat_get_activity which is indexed by PID. The function pg_stat_get_backend_idset provides a convenient way to generate one row for each active server process. For example, to show the PIDs and current queries of all server processes:

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;