Statistics Collector
Redrock Postgres’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 the total number of rows in each table, and information about analyze actions for each table. It can also count calls to user-defined functions and the total time spent in each one.
Redrock Postgres also supports reporting dynamic information about exactly what is going on in the system right now, such as the exact command currently being executed by other server processes, and which other connections exist in the system. This facility is independent of the collector process.
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 19 for details about setting configuration parameters.)
The parameter track_activities enables monitoring of the current command being executed by any server process.
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_io_timing enables monitoring of block read and write times.
The parameter track_wait_events controls whether statistics are collected about wait events.
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 transmits the collected information to other PostgreSQL processes through temporary files. These files are stored in the directory named by the stats_temp_directory parameter, pg_tmp/stats
by default. For better performance, stats_temp_directory
can be pointed at a RAM-based file system, decreasing physical I/O requirements. When the server shuts down cleanly, a permanent copy of the statistics data is stored in the pg_stat
subdirectory, so that statistics can be retained across server restarts. When recovery is performed at server start (e.g., after immediate shutdown, server crash, and point-in-time recovery), all statistics counters are reset.
Several predefined views, listed in Table 1, are available to show the current state of the system. There are also several other views, listed in Table 2, available to show the results of statistics collection. Alternatively, one can build custom views using the underlying statistics functions, as discussed in Statistics Functions.
When using the statistics to monitor collected data, 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 ms 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 show static information as long as you continue the current transaction. Similarly, information about the current queries of all sessions 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.
A transaction can also see its own statistics (as yet untransmitted to the collector) in the views pg_stat_xact_all_tables
, pg_stat_xact_all_undos
, pg_stat_xact_sys_tables
, pg_stat_xact_user_tables
, and pg_stat_xact_user_functions
. These numbers do not act as stated above; instead they update continuously throughout the transaction.
Some of the information in the dynamic statistics views shown in Table 1 is security restricted. Ordinary users can only see all the information about their own sessions (sessions belonging to a role that they are a member of). In rows about other sessions, many columns will be null. Note, however, that the existence of a session and its general properties such as its sessions user and database are visible to all users. Superusers and members of the built-in role pg_read_all_stats
(see also Section 21.5) can see all the information about all sessions.
Table 1. Dynamic Statistics Views
View Name | Description |
---|---|
pg_stat_activity |
One row per server process, showing information related to the current activity of that process, such as state and current query. See pg_stat_activity for details. |
pg_stat_wait_event |
One row per wait event, showing statistics about wait information of every occured wait events. See pg_stat_wait_event for details. |
pg_stat_replication |
One row per WAL sender process, showing statistics about replication to that sender’s connected standby server. See pg_stat_replication for details. |
Table 2. Collected Statistics Views
View Name | Description |
---|---|
pg_stat_database |
One row per database, showing database-wide statistics. See pg_stat_database for details. |
pg_stat_all_tables |
One row for each table in the current database, showing statistics about accesses to that specific table. See pg_stat_all_tables for details. |
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_xact_all_tables |
Similar to pg_stat_all_tables , but counts actions taken so far within the current transaction (which are not yet included in pg_stat_all_tables and related views). The columns for numbers of live and dead rows and analyze actions are not present in this view. |
pg_stat_xact_sys_tables |
Same as pg_stat_xact_all_tables , except that only system tables are shown. |
pg_stat_xact_user_tables |
Same as pg_stat_xact_all_tables , except that only user tables are shown. |
pg_stat_all_undos |
One row for each undo in the current database, showing statistics about accesses to that specific undo. See pg_stat_all_undos for details. |
pg_stat_xact_all_undos |
Similar to pg_stat_all_undos , but counts actions taken so far within the current transaction (which are not yet included in pg_stat_all_undos and related views). The columns for numbers of live and dead records are not present in this view. |
pg_stat_all_indexes |
One row for each index in the current database, showing statistics about accesses to that specific index. See pg_stat_all_indexes for details. |
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 |
One row for each table in the current database, showing statistics about I/O on that specific table. See pg_statio_all_tables for details. |
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_undos |
One row for each undo in the current database, showing statistics about I/O on that specific undo. See pg_statio_all_undos for details. |
pg_statio_all_indexes |
One row for each index in the current database, showing statistics about I/O on that specific index. See pg_statio_all_indexes for details. |
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 |
One row for each sequence in the current database, showing statistics about I/O on that specific sequence. See pg_statio_all_sequences for details. |
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. 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.
The pg_stat_activity
view will have one row per server process, showing information related to the current activity of that process.
Table 3. pg_stat_activity
View
Column | Type | Description |
---|---|---|
datid |
oid |
OID of the database this backend is connected to |
datname |
name |
Name of the database this backend is connected to |
pid |
integer |
Database process ID of this backend |
spid |
integer |
System process ID of this backend |
tid |
integer |
Database thread ID of this backend |
usesysid |
oid |
OID of the user logged into this backend |
usename |
name |
Name of the user logged into this backend |
application_name |
text |
Name of the application that is connected to this backend |
client_addr |
inet |
IP address of the client connected to this backend. If this field is null, it indicates either that the client is connected via a Unix socket on the server machine or that this is an internal process such as autoanalyze. |
client_hostname |
text |
Host name of the connected client, as reported by a reverse DNS lookup of client_addr . This field will only be non-null for IP connections, and only when log_hostname is enabled. |
client_port |
integer |
TCP port number that the client is using for communication with this backend, or -1 if a Unix socket is used |
backend_start |
timestamp with time zone |
Time when this process was started. For client backends, this is the time the client connected to the server. |
xact_start |
timestamp with time zone |
Time when this process’ current transaction was started, or null if no transaction is active. If the current query is the first of its transaction, this column is equal to the query_start column. |
query_start |
timestamp with time zone |
Time when the currently active query was started, or if state is not active , when the last query was started |
state_change |
timestamp with time zone |
Time when the state was last changed |
wait_event_type |
text |
The type of event for which the backend is waiting, if any; otherwise NULL. See Wait Event Types. |
wait_event |
text |
Wait event name if backend is currently waiting, otherwise NULL. See Waiting Events section for details. |
memory_used |
bigint |
Memory used by this backend. |
state |
text |
Current overall state of this backend. Possible values are:active : The backend is executing a query.idle : The backend is waiting for a new client command.idle in transaction : The backend is in a transaction, but is not currently executing a query.idle in transaction (aborted) : This state is similar to idle in transaction , except one of the statements in the transaction caused an error.fastpath function call : The backend is executing a fast-path function.disabled : This state is reported if track_activities is disabled in this backend. |
backend_xid |
xid |
Top-level transaction identifier of this backend, if any. |
backend_mintime |
logicaltime |
The current backend’s mintime horizon. |
query |
text |
Text of this backend’s most recent query. If state is active this field shows the currently executing query. In all other states, it shows the last query that was executed. By default the query text is truncated at 1024 bytes; this value can be changed via the parameter track_activity_query_size. |
backend_type |
text |
Type of current backend. Possible types are analyze launcher , analyze worker , logical replication launcher , logical replication worker , parallel worker , background writer , client backend , checkpointer , startup , walreceiver , walsender and walwriter . In addition, background workers registered by extensions may have additional types. |
Thewait_event
andstate
columns are independent. If a backend is in theactive
state, it may or may not bewaiting
on some event. If the state isactive
andwait_event
is non-null, it means that a query is being executed, but is being blocked somewhere in the system.
The pg_stat_wait_event
view will contain one row for each wait event in the current database, showing statistics about wait information of every occured wait events.
Table 4. pg_stat_wait_event
View
Column | Type | Description |
---|---|---|
wait_event_type |
text |
Type of the wait event. See Wait Event Types. |
wait_event |
text |
Name of the wait event. See Waiting Events section for details. |
waits |
bigint |
Number of times this event has occured |
total_time |
double precision |
Total time spent in the event, in milliseconds |
min_time |
double precision |
Minimum time spent in the event, in milliseconds |
max_time |
double precision |
Maximum time spent in the event, in milliseconds |
mean_time |
double precision |
Mean time spent in the event, in milliseconds |
The pg_stat_replication
view will contain one row per WAL sender process, showing statistics about replication to that sender’s connected standby server. Only directly connected standbys are listed; no information is available about downstream standby servers.
Table 5. pg_stat_replication
View
Column | Type | Description |
---|---|---|
pid |
integer |
Process ID of a WAL sender process |
usesysid |
oid |
OID of the user logged into this WAL sender process |
usename |
name |
Name of the user logged into this WAL sender process |
application_name |
text |
Name of the application that is connected to this WAL sender |
client_addr |
inet |
IP address of the client connected to this WAL sender. If this field is null, it indicates that the client is connected via a Unix socket on the server machine. |
client_hostname |
text |
Host name of the connected client, as reported by a reverse DNS lookup of client_addr . This field will only be non-null for IP connections, and only when log_hostname is enabled. |
client_port |
integer |
TCP port number that the client is using for communication with this WAL sender, or -1 if a Unix socket is used |
backend_start |
timestamp with time zone |
Time when this process was started, i.e., when the client connected to this WAL sender |
backend_mintime |
logicaltime |
This standby’s mintime horizon reported by hot_standby_feedback. |
state |
text |
Current WAL sender state. Possible values are:startup : This WAL sender is starting up.catchup : This WAL sender’s connected standby is catching up with the primary.streaming : This WAL sender is streaming changes after its connected standby server has caught up with the primary.backup : This WAL sender is sending a backup.stopping : This WAL sender is stopping. |
sent_lsn |
pg_lsn |
Last write-ahead log location sent on this connection |
write_lsn |
pg_lsn |
Last write-ahead log location written to disk by this standby server |
flush_lsn |
pg_lsn |
Last write-ahead log location flushed to disk by this standby server |
replay_lsn |
pg_lsn |
Last write-ahead log location replayed into the database on this standby server |
write_lag |
interval |
Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written it (but not yet flushed it or applied it). This can be used to gauge the delay that synchronous_commit level remote_write incurred while committing if this server was configured as a synchronous standby. |
flush_lag |
interval |
Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written and flushed it (but not yet applied it). This can be used to gauge the delay that synchronous_commit level on incurred while committing if this server was configured as a synchronous standby. |
replay_lag |
interval |
Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written, flushed and applied it. This can be used to gauge the delay that synchronous_commit level remote_apply incurred while committing if this server was configured as a synchronous standby. |
sync_priority |
integer |
Priority of this standby server for being chosen as the synchronous standby in a priority-based synchronous replication. This has no effect in a quorum-based synchronous replication. |
sync_state |
text |
Synchronous state of this standby server. Possible values are:async : This standby server is asynchronous.potential : This standby server is now asynchronous, but can potentially become synchronous if one of current synchronous ones fails.sync : This standby server is synchronous.quorum : This standby server is considered as a candidate for quorum standbys. |
reply_time |
timestamp with time zone |
Send time of last reply message received from standby server |
The lag times reported in the pg_stat_replication
view are measurements of the time taken for recent WAL to be written, flushed and replayed and for the sender to know about it. These times represent the commit delay that was (or would have been) introduced by each synchronous commit level, if the remote server was configured as a synchronous standby. For an asynchronous standby, the replay_lag
column approximates the delay before recent transactions became visible to queries. If the standby server has entirely caught up with the sending server and there is no more WAL activity, the most recently measured lag times will continue to be displayed for a short time and then show NULL.
Lag times work automatically for physical replication. Logical decoding plugins may optionally emit tracking messages; if they do not, the tracking mechanism will simply display NULL lag.
The reported lag times are not predictions of how long it will take for the standby to catch up with the sending server assuming the current rate of replay. Such a system would show similar times while new WAL is being generated, but would differ when the sender becomes idle. In particular, when the standby has caught up completely,pg_stat_replication
shows the time taken to write, flush and replay the most recent reported WAL location rather than zero as some users might expect. This is consistent with the goal of measuring synchronous commit and transaction visibility delays for recent write transactions. To reduce confusion for users expecting a different model of lag, the lag columns revert to NULL after a short time on a fully replayed idle system. Monitoring systems should choose whether to represent this as missing data, zero or continue to display the last known value.
The pg_stat_database
view will contain one row for each database in the instance, plus one for the shared objects, showing database-wide statistics.
Table 6. pg_stat_database
View
Column | Type | Description |
---|---|---|
datid |
oid |
OID of this database, or 0 for objects belonging to a shared relation |
datname |
name |
Name of this database, or NULL for the shared objects. |
numbackends |
integer |
Number of backends currently connected to this database, or NULL for the shared objects. This is the only column in this view that returns a value reflecting current state; all other columns return the accumulated values since the last reset. |
xact_commit |
bigint |
Number of transactions in this database that have been committed |
xact_rollback |
bigint |
Number of transactions in this database that have been rolled back |
blks_read |
bigint |
Number of disk blocks read in this database |
blks_cloned |
bigint |
Number of data buffers cloned in this database |
blks_hit |
bigint |
Number of times disk blocks were found already in the buffer cache, so that a read was not necessary (this only includes hits in the PostgreSQL buffer cache, not the operating system’s file system cache) |
tup_returned |
bigint |
Number of rows returned by queries in this database |
tup_fetched |
bigint |
Number of rows fetched by queries in this database |
tup_inserted |
bigint |
Number of rows inserted by queries in this database |
tup_updated |
bigint |
Number of rows updated by queries in this database |
tup_deleted |
bigint |
Number of rows deleted by queries in this database |
conflicts |
bigint |
Number of queries canceled due to conflicts with recovery in this database. (Conflicts occur only on standby servers; see pg_stat_database_conflicts for details.) |
temp_files |
bigint |
Number of temporary files created by queries in this database. All temporary files are counted, regardless of why the temporary file was created (e.g., sorting or hashing), and regardless of the log_temp_files setting. |
temp_bytes |
bigint |
Total amount of data written to temporary files by queries in this database. All temporary files are counted, regardless of why the temporary file was created, and regardless of the log_temp_files setting. |
deadlocks |
bigint |
Number of deadlocks detected in this database |
checksum_failures |
bigint |
Number of data page checksum failures detected in this database (or on a shared object), or NULL if data checksums are not enabled. |
checksum_last_failure |
timestamp with time zone |
Time at which the last data page checksum failure was detected in this database (or on a shared object), or NULL if data checksums are not enabled. |
blk_read_time |
double precision |
Time spent reading data file blocks by backends in this database, in milliseconds |
blk_clone_time |
double precision |
Time spent cloning data buffers by backends in this database, in milliseconds |
blk_write_time |
double precision |
Time spent writing data file blocks by backends in this database, in milliseconds |
stats_reset |
timestamp with time zone |
Time at which these statistics were last reset |
The pg_stat_all_tables
view will contain one row for each table in the current database (including TOAST tables), showing statistics about accesses to that specific table. The pg_stat_user_tables
and pg_stat_sys_tables
views contain the same information, but filtered to only show user and system tables respectively.
Table 7. pg_stat_all_tables
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of a table |
schemaname |
name |
Name of the schema that this table is in |
relname |
name |
Name of this table |
seq_scan |
bigint |
Number of sequential scans initiated on this table |
seq_tup_read |
bigint |
Number of live rows fetched by sequential scans |
idx_scan |
bigint |
Number of index scans initiated on this table |
idx_tup_fetch |
bigint |
Number of live rows fetched by index scans |
n_tup_ins |
bigint |
Number of rows inserted |
n_tup_upd |
bigint |
Number of rows updated (includes HOT updated rows) |
n_tup_del |
bigint |
Number of rows deleted |
n_tup_hot_upd |
bigint |
Number of rows HOT updated (i.e., with no separate index update required) |
n_live_tup |
bigint |
Estimated number of live rows |
n_dead_tup |
bigint |
Estimated number of dead rows |
n_mod_since_analyze |
bigint |
Estimated number of rows modified since this table was last analyzed |
last_analyze |
timestamp with time zone |
Last time at which this table was manually analyzed |
last_autoanalyze |
timestamp with time zone |
Last time at which this table was analyzed by the autoanalyze daemon |
analyze_count |
bigint |
Number of times this table has been manually analyzed |
autoanalyze_count |
bigint |
Number of times this table has been analyzed by the autoanalyze daemon |
The pg_stat_all_undos
view will contain one row for each undo in the current database, showing statistics about accesses to that specific undo.
Table 8. pg_stat_all_undos
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of this undo |
schemaname |
name |
Name of the schema that this undo is in |
relname |
name |
Name of this undo |
n_tup_fetch |
bigint |
Number of records fetched |
n_tup_ins |
bigint |
Number of records inserted |
n_tup_upd |
bigint |
Number of records updated |
n_tup_del |
bigint |
Number of records deleted |
n_tup_hot_upd |
bigint |
Number of records HOT updated |
n_live_tup |
bigint |
Estimated number of live records |
n_dead_tup |
bigint |
Estimated number of dead records |
The pg_stat_all_indexes
view will contain one row for each index in the current database, showing statistics about accesses to that specific index. The pg_stat_user_indexes
and pg_stat_sys_indexes
views contain the same information, but filtered to only show user and system indexes respectively.
Table 9. pg_stat_all_indexes
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of the table for this index |
indexrelid |
oid |
OID of this index |
schemaname |
name |
Name of the schema this index is in |
relname |
name |
Name of the table for this index |
indexrelname |
name |
Name of this index |
idx_scan |
bigint |
Number of index scans initiated on this index |
idx_tup_read |
bigint |
Number of index entries returned by scans on this index |
idx_tup_fetch |
bigint |
Number of live table rows fetched by simple index scans using this index |
Indexes can be used by simple index scans, “bitmap” index scans, and the optimizer. 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
. The optimizer also accesses indexes to check for supplied constants whose values are outside the recorded range of the optimizer statistics because the optimizer statistics might be stale.
Theidx_tup_read
andidx_tup_fetch
counts can be different even without any use of bitmap scans, becauseidx_tup_read
counts index entries retrieved from the index whileidx_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, or if any heap fetches are avoided by means of an index-only scan.
The pg_statio_all_tables
view will contain one row for each table in the current database (including TOAST tables), showing statistics about I/O on that specific table. The pg_statio_user_tables
and pg_statio_sys_tables
views contain the same information, but filtered to only show user and system tables respectively.
Table 10. pg_statio_all_tables
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of a table |
schemaname |
name |
Name of the schema that this table is in |
relname |
name |
Name of this table |
heap_blks_read |
bigint |
Number of disk blocks read from this table |
heap_blks_cloned |
bigint |
Number of data buffers cloned from this table |
heap_blks_hit |
bigint |
Number of buffer hits in this table |
idx_blks_read |
bigint |
Number of disk blocks read from all indexes on this table |
idx_blks_cloned |
bigint |
Number of data buffers cloned from all indexes on this table |
idx_blks_hit |
bigint |
Number of buffer hits in all indexes on this table |
toast_blks_read |
bigint |
Number of disk blocks read from this table’s TOAST table (if any) |
toast_blks_cloned |
bigint |
Number of data buffers cloned from this table’s TOAST table (if any) |
toast_blks_hit |
bigint |
Number of buffer hits in this table’s TOAST table (if any) |
tidx_blks_read |
bigint |
Number of disk blocks read from this table’s TOAST table indexes (if any) |
tidx_blks_cloned |
bigint |
Number of data buffers cloned from this table’s TOAST table indexes (if any) |
tidx_blks_hit |
bigint |
Number of buffer hits in this table’s TOAST table indexes (if any) |
The pg_statio_all_undos
view will contain one row for each undo in the current database, showing statistics about I/O on that specific undo.
Table 11. pg_statio_all_undos
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of the table for this index |
schemaname |
name |
Name of the schema this undois in |
relname |
name |
Name of the table for this undo |
undo_blks_read |
bigint |
Number of disk blocks read from this undo |
undo_blks_cloned |
bigint |
Number of data buffers cloned from this undo |
undo_blks_hit |
bigint |
Number of buffer hits in this undo |
The pg_statio_all_indexes
view will contain one row for each index in the current database, showing statistics about I/O on that specific index. The pg_statio_user_indexes
and pg_statio_sys_indexes
views contain the same information, but filtered to only show user and system indexes respectively.
Table 12. pg_statio_all_indexes
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of the table for this index |
indexrelid |
oid |
OID of this index |
schemaname |
name |
Name of the schema this index is in |
relname |
name |
Name of the table for this index |
indexrelname |
name |
Name of this index |
idx_blks_read |
bigint |
Number of disk blocks read from this index |
idx_blks_cloned |
bigint |
Number of data buffers cloned from this index |
idx_blks_hit |
bigint |
Number of buffer hits in this index |
The pg_statio_all_sequences
view will contain one row for each sequence in the current database, showing statistics about I/O on that specific sequence.
Table 13. pg_statio_all_sequences
View
Column | Type | Description |
---|---|---|
relid |
oid |
OID of a sequence |
schemaname |
name |
Name of the schema this sequence is in |
relname |
name |
Name of this sequence |
blks_read |
bigint |
Number of disk blocks read from this sequence |
blks_cloned |
bigint |
Number of data buffers cloned from this sequence |
blks_hit |
bigint |
Number of buffer hits in this sequence |
Other ways of looking at the statistics can be set up by writing queries that use the same underlying statistics access functions used by the standard views shown above. For details such as the functions’ names, consult the definitions of the standard views. (For example, in psql you could issue \d+ pg_stat_activity
.) The access functions for per-database statistics take a database OID as an argument to identify which database to report on. The per-table and per-index functions take a table or index OID. The functions for per-function statistics take a function OID. Note that only tables, indexes, and functions in the current database can be seen with these functions.
Additional functions related to statistics collection are listed in Table 14.
Table 14. Additional Statistics Functions
Function | Description |
---|---|
pg_backend_pid () → integer | Database process ID of the backend handling the current session |
pg_backend_spid () → integer | Operating system process ID of the backend handling the current session |
pg_backend_tid () → integer | Database thread ID of the backend handling 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 a subset of those in the pg_stat_activity view. |
pg_stat_get_wait_event ( integer ) → setof record | Returns a result set of information about the backend with the specified PID, or a summarized result set of all active backends in the system if NULL is specified. The fields returned are a subset of those in the pg_stat_wait_event view. |
pg_stat_get_snapshot_timestamp () → timestamp with time zone | Returns the timestamp of the current statistics snapshot |
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 by default, but EXECUTE for this function can be granted to others.) |
pg_stat_reset_shared ( text ) → void | Reset some instance-wide statistics counters to zero, depending on the argument (requires superuser privileges by default, but EXECUTE for this function can be granted to others). Calling pg_stat_reset_shared('bgwriter') will zero all the counters shown in the pg_stat_bgwriter view. Calling pg_stat_reset_shared('archiver') will zero all the counters shown in the pg_stat_archiver view. |
pg_stat_reset_wait_event ( integer ) → void | Reset statistics counters about wait events for the backend with the specified PID to zero, or reset statistics counters about wait events for all backends in the system if NULL is specified. (requires superuser privileges by default, but EXECUTE for this function can be granted to others.) |
pg_stat_reset_single_table_counters ( oid ) → void | Reset statistics for a single table or index in the current database to zero (requires superuser privileges by default, but EXECUTE for this function can be granted to others) |
pg_stat_reset_single_function_counters ( oid ) → void | Reset statistics for a single function in the current database to zero (requires superuser privileges by default, but EXECUTE for this function can be granted to others) |
pg_stat_get_activity
, the underlying function of the pg_stat_activity
view, returns a set of records containing all the available information about each backend process. Sometimes it may be more convenient to obtain just a subset of this information. In such cases, an older set of per-backend statistics access functions can be used; these are shown in Table 15. These access functions use a backend ID number, which ranges from one to the number of currently active backends. The function pg_stat_get_backend_idset
provides a convenient way to generate one row for each active backend for invoking these functions. For example, to show the PIDs and current queries of all backends:
SELECT pg_stat_get_backend_pid(s.backendid) AS pid,
pg_stat_get_backend_activity(s.backendid) AS query
FROM (SELECT pg_stat_get_backend_idset() AS backendid) AS s;
Table 15. Per-Backend Statistics Functions
Function | Description |
---|---|
pg_stat_get_backend_idset () → setof integer | Set of currently active backend ID numbers (from 1 to the number of active backends) |
pg_stat_get_backend_activity ( integer ) → text | Text of this backend’s most recent query |
pg_stat_get_backend_activity_start ( integer ) → timestamp with time zone | Time when the most recent query was started |
pg_stat_get_backend_client_addr ( integer ) → inet | IP address of the client connected to this backend |
pg_stat_get_backend_client_port ( integer ) → integer | TCP port number that the client is using for communication |
pg_stat_get_backend_dbid ( integer ) → oid | OID of the database this backend is connected to |
pg_stat_get_backend_pid ( integer ) → integer | Database process ID of this backend |
pg_stat_get_backend_spid ( integer ) → integer | Operating system process ID of this backend |
pg_stat_get_backend_tid ( integer ) → integer | Database thread ID of this backend |
pg_stat_get_backend_start ( integer ) → timestamp with time zone | Time when this process was started |
pg_stat_get_backend_userid ( integer ) → oid | OID of the user logged into this backend |
pg_stat_get_backend_wait_event_type ( integer ) → text | Wait event type name if backend is currently waiting, otherwise NULL. See Wait Event Types. |
pg_stat_get_backend_wait_event ( integer ) → text | Wait event name if backend is currently waiting, otherwise NULL. See Waiting Events section for details. |
pg_stat_get_backend_memory_used ( integer ) → bigint | Memory used by this backend. |
pg_stat_get_backend_xact_start ( integer ) → timestamp with time zone | Time when the current transaction was started |