pg_stat_activity
pg_stat_replication
pg_stat_replication_slots
pg_stat_wal_receiver
pg_stat_recovery_prefetch
pg_stat_subscription
pg_stat_subscription_stats
pg_stat_ssl
pg_stat_gssapi
pg_stat_archiver
pg_stat_io
pg_stat_bgwriter
pg_stat_wal
pg_stat_database
pg_stat_database_conflicts
pg_stat_all_tables
pg_stat_all_indexes
pg_statio_all_tables
pg_statio_all_indexes
pg_statio_all_sequences
pg_stat_user_functions
pg_stat_slru
PostgreSQL's cumulative statistics system supports collection and reporting of information about server activity. Presently, accesses to tables and indexes in both disk-block and individual-row terms are counted. The total number of rows in each table, and information about vacuum and analyze actions for each table are also counted. If enabled, calls to user-defined functions and the total time spent in each one are counted as well.
PostgreSQL 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 cumulative statistics system.
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 20 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 cumulative 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_wal_io_timing enables monitoring of WAL write times.
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
.)
Cumulative statistics are collected in shared memory. Every
PostgreSQL process collects statistics locally,
then updates the shared data at appropriate intervals. When a server,
including a physical replica, 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. In contrast,
when starting from an unclean shutdown (e.g., after an immediate shutdown,
a server crash, starting from a base backup, and point-in-time recovery),
all statistics counters are reset.
Several predefined views, listed in Table 28.1, are available to show the current state of the system. There are also several other views, listed in Table 28.2, available to show the accumulated statistics. Alternatively, one can build custom views using the underlying cumulative statistics functions, as discussed in Section 28.2.25.
When using the cumulative statistics views and functions to monitor
collected data, it is important to realize that the information does not
update instantaneously. Each individual server process flushes out
accumulated statistics to shared memory just before going idle, but not
more frequently than once per PGSTAT_MIN_INTERVAL
milliseconds (1 second unless altered while building the server); so a
query or transaction still in progress does not affect the displayed totals
and 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 the accumulated statistics, accessed values are cached until the end
of its current transaction in the default configuration. 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.
When analyzing statistics interactively, or with expensive queries, the
time delta between accesses to individual statistics can lead to
significant skew in the cached statistics. To minimize skew,
stats_fetch_consistency
can be set to
snapshot
, at the price of increased memory usage for
caching not-needed statistics data. Conversely, if it's known that
statistics are only accessed once, caching accessed statistics is
unnecessary and can be avoided by setting
stats_fetch_consistency
to none
.
You can invoke pg_stat_clear_snapshot
() to discard the
current transaction's statistics snapshot or cached values (if any). The
next use of statistical information will (when in snapshot mode) cause a
new snapshot to be built or (when in cache mode) accessed statistics to be
cached.
A transaction can also see its own statistics (not yet flushed out to the
shared memory statistics) in the views
pg_stat_xact_all_tables
,
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 28.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 roles with privileges of
built-in role pg_read_all_stats
(see also Section 22.5) can see all the information about all sessions.
Table 28.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_replication | One row per WAL sender process, showing statistics about
replication to that sender's connected standby server.
See
pg_stat_replication for details.
|
pg_stat_wal_receiver | Only one row, showing statistics about the WAL receiver from
that receiver's connected server.
See
pg_stat_wal_receiver for details.
|
pg_stat_recovery_prefetch | Only one row, showing statistics about blocks prefetched during recovery.
See
pg_stat_recovery_prefetch for details.
|
pg_stat_subscription | At least one row per subscription, showing information about
the subscription workers.
See
pg_stat_subscription for details.
|
pg_stat_ssl | One row per connection (regular and replication), showing information about
SSL used on this connection.
See
pg_stat_ssl for details.
|
pg_stat_gssapi | One row per connection (regular and replication), showing information about
GSSAPI authentication and encryption used on this connection.
See
pg_stat_gssapi for details.
|
pg_stat_progress_analyze | One row for each backend (including autovacuum worker processes) running
ANALYZE , showing current progress.
See Section 28.4.1.
|
pg_stat_progress_create_index | One row for each backend running CREATE INDEX or REINDEX , showing
current progress.
See Section 28.4.4.
|
pg_stat_progress_vacuum | One row for each backend (including autovacuum worker processes) running
VACUUM , showing current progress.
See Section 28.4.5.
|
pg_stat_progress_cluster | One row for each backend running
CLUSTER or VACUUM FULL , showing current progress.
See Section 28.4.2.
|
pg_stat_progress_basebackup | One row for each WAL sender process streaming a base backup, showing current progress. See Section 28.4.6. |
pg_stat_progress_copy | One row for each backend running COPY , showing current progress.
See Section 28.4.3.
|
Table 28.2. Collected Statistics Views
View Name | Description |
---|---|
pg_stat_archiver | One row only, showing statistics about the
WAL archiver process's activity. See
pg_stat_archiver for details.
|
pg_stat_bgwriter | One row only, showing statistics about the
background writer process's activity. See
pg_stat_bgwriter for details.
|
pg_stat_database | One row per database, showing database-wide statistics. See
pg_stat_database for details.
|
pg_stat_database_conflicts |
One row per database, showing database-wide statistics about
query cancels due to conflict with recovery on standby servers.
See
pg_stat_database_conflicts for details.
|
pg_stat_io |
One row for each combination of backend type, context, and target object
containing cluster-wide I/O statistics.
See
pg_stat_io for details.
|
pg_stat_replication_slots | One row per replication slot, showing statistics about the
replication slot's usage. See
pg_stat_replication_slots for details.
|
pg_stat_slru | One row per SLRU, showing statistics of operations. See
pg_stat_slru for details.
|
pg_stat_subscription_stats | One row per subscription, showing statistics about errors.
See
pg_stat_subscription_stats for details.
|
pg_stat_wal | One row only, showing statistics about WAL activity. See
pg_stat_wal 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 vacuum 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_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_stat_user_functions |
One row for each tracked function, showing statistics
about executions of that function. See
pg_stat_user_functions for details.
|
pg_stat_xact_user_functions | Similar to pg_stat_user_functions , but counts only
calls during the current transaction (which are not
yet included in pg_stat_user_functions ). |
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_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_stat_io
and
pg_statio_
set of views are useful for determining
the effectiveness of the buffer cache. They can be used to calculate a cache
hit ratio. Note that while PostgreSQL's I/O
statistics capture most instances in which the kernel was invoked in order
to perform I/O, they do not differentiate between data which had to be
fetched from disk and that which already resided in the kernel page cache.
Users are advised to use the PostgreSQL
statistics views in combination with operating system utilities for a more
complete picture of their database's I/O performance.
pg_stat_activity
#
The pg_stat_activity
view will have one row
per server process, showing information related to
the current activity of that process.
Table 28.3. pg_stat_activity
View
Column Type Description |
---|
OID of the database this backend is connected to |
Name of the database this backend is connected to |
Process ID of this backend |
Process ID of the parallel group leader if this process is a parallel
query worker, or process ID of the leader apply worker if this process
is a parallel apply worker. |
OID of the user logged into this backend |
Name of the user logged into this backend |
Name of the application that is connected to this backend |
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 autovacuum. |
Host name of the connected client, as reported by a
reverse DNS lookup of |
TCP port number that the client is using for communication
with this backend, or |
Time when this process was started. For client backends, this is the time the client connected to the server. |
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
|
Time when the currently active query was started, or if
|
Time when the |
The type of event for which the backend is waiting, if any; otherwise NULL. See Table 28.4. |
Wait event name if backend is currently waiting, otherwise NULL. See Table 28.5 through Table 28.13. |
Current overall state of this backend. Possible values are:
|
Top-level transaction identifier of this backend, if any; see Section 74.1. |
The current backend's |
Identifier of this backend's most recent query. If
|
Text of this backend's most recent query. If
|
Type of current backend. Possible types are
|
The wait_event
and state
columns are
independent. If a backend is in the active
state,
it may or may not be waiting
on some event. If the state
is active
and wait_event
is non-null, it
means that a query is being executed, but is being blocked somewhere
in the system.
Table 28.4. Wait Event Types
Wait Event Type | Description |
---|---|
Activity | The server process is idle. This event type indicates a process
waiting for activity in its main processing loop.
wait_event will identify the specific wait point;
see Table 28.5.
|
BufferPin | The server process is waiting for exclusive access to a data buffer. Buffer pin waits can be protracted if another process holds an open cursor that last read data from the buffer in question. See Table 28.6. |
Client | The server process is waiting for activity on a socket
connected to a user application. Thus, the server expects something
to happen that is independent of its internal processes.
wait_event will identify the specific wait point;
see Table 28.7.
|
Extension | The server process is waiting for some condition defined by an extension module. See Table 28.8. |
IO | The server process is waiting for an I/O operation to complete.
wait_event will identify the specific wait point;
see Table 28.9.
|
IPC | The server process is waiting for some interaction with
another server process. wait_event will
identify the specific wait point;
see Table 28.10.
|
Lock | The server process is waiting for a heavyweight lock.
Heavyweight locks, also known as lock manager locks or simply locks,
primarily protect SQL-visible objects such as tables. However,
they are also used to ensure mutual exclusion for certain internal
operations such as relation extension. wait_event
will identify the type of lock awaited;
see Table 28.11.
|
LWLock | The server process is waiting for a lightweight lock.
Most such locks protect a particular data structure in shared memory.
wait_event will contain a name identifying the purpose
of the lightweight lock. (Some locks have specific names; others
are part of a group of locks each with a similar purpose.)
See Table 28.12.
|
Timeout | The server process is waiting for a timeout
to expire. wait_event will identify the specific wait
point; see Table 28.13.
|
Table 28.5. Wait Events of Type Activity
Activity Wait Event | Description |
---|---|
ArchiverMain | Waiting in main loop of archiver process. |
AutoVacuumMain | Waiting in main loop of autovacuum launcher process. |
BgWriterHibernate | Waiting in background writer process, hibernating. |
BgWriterMain | Waiting in main loop of background writer process. |
CheckpointerMain | Waiting in main loop of checkpointer process. |
LogicalApplyMain | Waiting in main loop of logical replication apply process. |
LogicalLauncherMain | Waiting in main loop of logical replication launcher process. |
LogicalParallelApplyMain | Waiting in main loop of logical replication parallel apply process. |
RecoveryWalStream | Waiting in main loop of startup process for WAL to arrive, during streaming recovery. |
SysLoggerMain | Waiting in main loop of syslogger process. |
WalReceiverMain | Waiting in main loop of WAL receiver process. |
WalSenderMain | Waiting in main loop of WAL sender process. |
WalWriterMain | Waiting in main loop of WAL writer process. |
Table 28.6. Wait Events of Type BufferPin
BufferPin Wait Event | Description |
---|---|
BufferPin | Waiting to acquire an exclusive pin on a buffer. |
Table 28.7. Wait Events of Type Client
Client Wait Event | Description |
---|---|
ClientRead | Waiting to read data from the client. |
ClientWrite | Waiting to write data to the client. |
GSSOpenServer | Waiting to read data from the client while establishing a GSSAPI session. |
LibPQWalReceiverConnect | Waiting in WAL receiver to establish connection to remote server. |
LibPQWalReceiverReceive | Waiting in WAL receiver to receive data from remote server. |
SSLOpenServer | Waiting for SSL while attempting connection. |
WalSenderWaitForWAL | Waiting for WAL to be flushed in WAL sender process. |
WalSenderWriteData | Waiting for any activity when processing replies from WAL receiver in WAL sender process. |
Table 28.8. Wait Events of Type Extension
Extension Wait Event | Description |
---|---|
Extension | Waiting in an extension. |
Table 28.9. Wait Events of Type IO
IO Wait Event | Description |
---|---|
BaseBackupRead | Waiting for base backup to read from a file. |
BaseBackupSync | Waiting for data written by a base backup to reach durable storage. |
BaseBackupWrite | Waiting for base backup to write to a file. |
BufFileRead | Waiting for a read from a buffered file. |
BufFileTruncate | Waiting for a buffered file to be truncated. |
BufFileWrite | Waiting for a write to a buffered file. |
ControlFileRead | Waiting for a read from the pg_control
file. |
ControlFileSync | Waiting for the pg_control file to reach
durable storage. |
ControlFileSyncUpdate | Waiting for an update to the pg_control file
to reach durable storage. |
ControlFileWrite | Waiting for a write to the pg_control
file. |
ControlFileWriteUpdate | Waiting for a write to update the pg_control
file. |
CopyFileRead | Waiting for a read during a file copy operation. |
CopyFileWrite | Waiting for a write during a file copy operation. |
DSMAllocate | Waiting for a dynamic shared memory segment to be allocated. |
DSMFillZeroWrite | Waiting to fill a dynamic shared memory backing file with zeroes. |
DataFileExtend | Waiting for a relation data file to be extended. |
DataFileFlush | Waiting for a relation data file to reach durable storage. |
DataFileImmediateSync | Waiting for an immediate synchronization of a relation data file to durable storage. |
DataFilePrefetch | Waiting for an asynchronous prefetch from a relation data file. |
DataFileRead | Waiting for a read from a relation data file. |
DataFileSync | Waiting for changes to a relation data file to reach durable storage. |
DataFileTruncate | Waiting for a relation data file to be truncated. |
DataFileWrite | Waiting for a write to a relation data file. |
LockFileAddToDataDirRead | Waiting for a read while adding a line to the data directory lock file. |
LockFileAddToDataDirSync | Waiting for data to reach durable storage while adding a line to the data directory lock file. |
LockFileAddToDataDirWrite | Waiting for a write while adding a line to the data directory lock file. |
LockFileCreateRead | Waiting to read while creating the data directory lock file. |
LockFileCreateSync | Waiting for data to reach durable storage while creating the data directory lock file. |
LockFileCreateWrite | Waiting for a write while creating the data directory lock file. |
LockFileReCheckDataDirRead | Waiting for a read during recheck of the data directory lock file. |
LogicalRewriteCheckpointSync | Waiting for logical rewrite mappings to reach durable storage during a checkpoint. |
LogicalRewriteMappingSync | Waiting for mapping data to reach durable storage during a logical rewrite. |
LogicalRewriteMappingWrite | Waiting for a write of mapping data during a logical rewrite. |
LogicalRewriteSync | Waiting for logical rewrite mappings to reach durable storage. |
LogicalRewriteTruncate | Waiting for truncate of mapping data during a logical rewrite. |
LogicalRewriteWrite | Waiting for a write of logical rewrite mappings. |
RelationMapRead | Waiting for a read of the relation map file. |
RelationMapReplace | Waiting for durable replacement of a relation map file. |
RelationMapWrite | Waiting for a write to the relation map file. |
ReorderBufferRead | Waiting for a read during reorder buffer management. |
ReorderBufferWrite | Waiting for a write during reorder buffer management. |
ReorderLogicalMappingRead | Waiting for a read of a logical mapping during reorder buffer management. |
ReplicationSlotRead | Waiting for a read from a replication slot control file. |
ReplicationSlotRestoreSync | Waiting for a replication slot control file to reach durable storage while restoring it to memory. |
ReplicationSlotSync | Waiting for a replication slot control file to reach durable storage. |
ReplicationSlotWrite | Waiting for a write to a replication slot control file. |
SLRUFlushSync | Waiting for SLRU data to reach durable storage during a checkpoint or database shutdown. |
SLRURead | Waiting for a read of an SLRU page. |
SLRUSync | Waiting for SLRU data to reach durable storage following a page write. |
SLRUWrite | Waiting for a write of an SLRU page. |
SnapbuildRead | Waiting for a read of a serialized historical catalog snapshot. |
SnapbuildSync | Waiting for a serialized historical catalog snapshot to reach durable storage. |
SnapbuildWrite | Waiting for a write of a serialized historical catalog snapshot. |
TimelineHistoryFileSync | Waiting for a timeline history file received via streaming replication to reach durable storage. |
TimelineHistoryFileWrite | Waiting for a write of a timeline history file received via streaming replication. |
TimelineHistoryRead | Waiting for a read of a timeline history file. |
TimelineHistorySync | Waiting for a newly created timeline history file to reach durable storage. |
TimelineHistoryWrite | Waiting for a write of a newly created timeline history file. |
TwophaseFileRead | Waiting for a read of a two phase state file. |
TwophaseFileSync | Waiting for a two phase state file to reach durable storage. |
TwophaseFileWrite | Waiting for a write of a two phase state file. |
VersionFileSync | Waiting for the version file to reach durable storage while creating a database. |
VersionFileWrite | Waiting for the version file to be written while creating a database. |
WALBootstrapSync | Waiting for WAL to reach durable storage during bootstrapping. |
WALBootstrapWrite | Waiting for a write of a WAL page during bootstrapping. |
WALCopyRead | Waiting for a read when creating a new WAL segment by copying an existing one. |
WALCopySync | Waiting for a new WAL segment created by copying an existing one to reach durable storage. |
WALCopyWrite | Waiting for a write when creating a new WAL segment by copying an existing one. |
WALInitSync | Waiting for a newly initialized WAL file to reach durable storage. |
WALInitWrite | Waiting for a write while initializing a new WAL file. |
WALRead | Waiting for a read from a WAL file. |
WALSenderTimelineHistoryRead | Waiting for a read from a timeline history file during a walsender timeline command. |
WALSync | Waiting for a WAL file to reach durable storage. |
WALSyncMethodAssign | Waiting for data to reach durable storage while assigning a new WAL sync method. |
WALWrite | Waiting for a write to a WAL file. |
Table 28.10. Wait Events of Type IPC
IPC Wait Event | Description |
---|---|
AppendReady | Waiting for subplan nodes of an Append plan
node to be ready. |
ArchiveCleanupCommand | Waiting for archive_cleanup_command to complete. |
ArchiveCommand | Waiting for archive_command to complete. |
BackendTermination | Waiting for the termination of another backend. |
BackupWaitWalArchive | Waiting for WAL files required for a backup to be successfully archived. |
BgWorkerShutdown | Waiting for background worker to shut down. |
BgWorkerStartup | Waiting for background worker to start up. |
BtreePage | Waiting for the page number needed to continue a parallel B-tree scan to become available. |
BufferIO | Waiting for buffer I/O to complete. |
CheckpointDone | Waiting for a checkpoint to complete. |
CheckpointStart | Waiting for a checkpoint to start. |
ExecuteGather | Waiting for activity from a child process while
executing a Gather plan node. |
HashBatchAllocate | Waiting for an elected Parallel Hash participant to allocate a hash table. |
HashBatchElect | Waiting to elect a Parallel Hash participant to allocate a hash table. |
HashBatchLoad | Waiting for other Parallel Hash participants to finish loading a hash table. |
HashBuildAllocate | Waiting for an elected Parallel Hash participant to allocate the initial hash table. |
HashBuildElect | Waiting to elect a Parallel Hash participant to allocate the initial hash table. |
HashBuildHashInner | Waiting for other Parallel Hash participants to finish hashing the inner relation. |
HashBuildHashOuter | Waiting for other Parallel Hash participants to finish partitioning the outer relation. |
HashGrowBatchesDecide | Waiting to elect a Parallel Hash participant to decide on future batch growth. |
HashGrowBatchesElect | Waiting to elect a Parallel Hash participant to allocate more batches. |
HashGrowBatchesFinish | Waiting for an elected Parallel Hash participant to decide on future batch growth. |
HashGrowBatchesReallocate | Waiting for an elected Parallel Hash participant to allocate more batches. |
HashGrowBatchesRepartition | Waiting for other Parallel Hash participants to finish repartitioning. |
HashGrowBucketsElect | Waiting to elect a Parallel Hash participant to allocate more buckets. |
HashGrowBucketsReallocate | Waiting for an elected Parallel Hash participant to finish allocating more buckets. |
HashGrowBucketsReinsert | Waiting for other Parallel Hash participants to finish inserting tuples into new buckets. |
LogicalApplySendData | Waiting for a logical replication leader apply process to send data to a parallel apply process. |
LogicalParallelApplyStateChange | Waiting for a logical replication parallel apply process to change state. |
LogicalSyncData | Waiting for a logical replication remote server to send data for initial table synchronization. |
LogicalSyncStateChange | Waiting for a logical replication remote server to change state. |
MessageQueueInternal | Waiting for another process to be attached to a shared message queue. |
MessageQueuePutMessage | Waiting to write a protocol message to a shared message queue. |
MessageQueueReceive | Waiting to receive bytes from a shared message queue. |
MessageQueueSend | Waiting to send bytes to a shared message queue. |
ParallelBitmapScan | Waiting for parallel bitmap scan to become initialized. |
ParallelCreateIndexScan | Waiting for parallel CREATE INDEX workers to
finish heap scan. |
ParallelFinish | Waiting for parallel workers to finish computing. |
ProcArrayGroupUpdate | Waiting for the group leader to clear the transaction ID at end of a parallel operation. |
ProcSignalBarrier | Waiting for a barrier event to be processed by all backends. |
Promote | Waiting for standby promotion. |
RecoveryConflictSnapshot | Waiting for recovery conflict resolution for a vacuum cleanup. |
RecoveryConflictTablespace | Waiting for recovery conflict resolution for dropping a tablespace. |
RecoveryEndCommand | Waiting for recovery_end_command to complete. |
RecoveryPause | Waiting for recovery to be resumed. |
ReplicationOriginDrop | Waiting for a replication origin to become inactive so it can be dropped. |
ReplicationSlotDrop | Waiting for a replication slot to become inactive so it can be dropped. |
RestoreCommand | Waiting for restore_command to complete. |
SafeSnapshot | Waiting to obtain a valid snapshot for a READ ONLY
DEFERRABLE transaction. |
SyncRep | Waiting for confirmation from a remote server during synchronous replication. |
WalReceiverExit | Waiting for the WAL receiver to exit. |
WalReceiverWaitStart | Waiting for startup process to send initial data for streaming replication. |
XactGroupUpdate | Waiting for the group leader to update transaction status at end of a parallel operation. |
Table 28.11. Wait Events of Type Lock
Lock Wait Event | Description |
---|---|
advisory | Waiting to acquire an advisory user lock. |
applytransaction | Waiting to acquire a lock on a remote transaction being applied by a logical replication subscriber. |
extend | Waiting to extend a relation. |
frozenid | Waiting to
update pg_database .datfrozenxid
and pg_database .datminmxid . |
object | Waiting to acquire a lock on a non-relation database object. |
page | Waiting to acquire a lock on a page of a relation. |
relation | Waiting to acquire a lock on a relation. |
spectoken | Waiting to acquire a speculative insertion lock. |
transactionid | Waiting for a transaction to finish. |
tuple | Waiting to acquire a lock on a tuple. |
userlock | Waiting to acquire a user lock. |
virtualxid | Waiting to acquire a virtual transaction ID lock; see Section 74.1. |
Table 28.12. Wait Events of Type LWLock
LWLock Wait Event | Description |
---|---|
AddinShmemInit | Waiting to manage an extension's space allocation in shared memory. |
AutoFile | Waiting to update the postgresql.auto.conf
file. |
Autovacuum | Waiting to read or update the current state of autovacuum workers. |
AutovacuumSchedule | Waiting to ensure that a table selected for autovacuum still needs vacuuming. |
BackgroundWorker | Waiting to read or update background worker state. |
BtreeVacuum | Waiting to read or update vacuum-related information for a B-tree index. |
BufferContent | Waiting to access a data page in memory. |
BufferMapping | Waiting to associate a data block with a buffer in the buffer pool. |
CheckpointerComm | Waiting to manage fsync requests. |
CommitTs | Waiting to read or update the last value set for a transaction commit timestamp. |
CommitTsBuffer | Waiting for I/O on a commit timestamp SLRU buffer. |
CommitTsSLRU | Waiting to access the commit timestamp SLRU cache. |
ControlFile | Waiting to read or update the pg_control
file or create a new WAL file. |
DynamicSharedMemoryControl | Waiting to read or update dynamic shared memory allocation information. |
LockFastPath | Waiting to read or update a process' fast-path lock information. |
LockManager | Waiting to read or update information about “heavyweight” locks. |
LogicalRepLauncherDSA | Waiting to access logical replication launcher's dynamic shared memory allocator. |
LogicalRepLauncherHash | Waiting to access logical replication launcher's shared hash table. |
LogicalRepWorker | Waiting to read or update the state of logical replication workers. |
MultiXactGen | Waiting to read or update shared multixact state. |
MultiXactMemberBuffer | Waiting for I/O on a multixact member SLRU buffer. |
MultiXactMemberSLRU | Waiting to access the multixact member SLRU cache. |
MultiXactOffsetBuffer | Waiting for I/O on a multixact offset SLRU buffer. |
MultiXactOffsetSLRU | Waiting to access the multixact offset SLRU cache. |
MultiXactTruncation | Waiting to read or truncate multixact information. |
NotifyBuffer | Waiting for I/O on a NOTIFY message SLRU
buffer. |
NotifyQueue | Waiting to read or update NOTIFY messages. |
NotifyQueueTail | Waiting to update limit on NOTIFY message
storage. |
NotifySLRU | Waiting to access the NOTIFY message SLRU
cache. |
OidGen | Waiting to allocate a new OID. |
OldSnapshotTimeMap | Waiting to read or update old snapshot control information. |
ParallelAppend | Waiting to choose the next subplan during Parallel Append plan execution. |
ParallelHashJoin | Waiting to synchronize workers during Parallel Hash Join plan execution. |
ParallelQueryDSA | Waiting for parallel query dynamic shared memory allocation. |
PerSessionDSA | Waiting for parallel query dynamic shared memory allocation. |
PerSessionRecordType | Waiting to access a parallel query's information about composite types. |
PerSessionRecordTypmod | Waiting to access a parallel query's information about type modifiers that identify anonymous record types. |
PerXactPredicateList | Waiting to access the list of predicate locks held by the current serializable transaction during a parallel query. |
PgStatsData | Waiting for shared memory stats data access |
PgStatsDSA | Waiting for stats dynamic shared memory allocator access |
PgStatsHash | Waiting for stats shared memory hash table access |
PredicateLockManager | Waiting to access predicate lock information used by serializable transactions. |
ProcArray | Waiting to access the shared per-process data structures (typically, to get a snapshot or report a session's transaction ID). |
RelationMapping | Waiting to read or update
a pg_filenode.map file (used to track the
filenode assignments of certain system catalogs). |
RelCacheInit | Waiting to read or update a pg_internal.init
relation cache initialization file. |
ReplicationOrigin | Waiting to create, drop or use a replication origin. |
ReplicationOriginState | Waiting to read or update the progress of one replication origin. |
ReplicationSlotAllocation | Waiting to allocate or free a replication slot. |
ReplicationSlotControl | Waiting to read or update replication slot state. |
ReplicationSlotIO | Waiting for I/O on a replication slot. |
SerialBuffer | Waiting for I/O on a serializable transaction conflict SLRU buffer. |
SerializableFinishedList | Waiting to access the list of finished serializable transactions. |
SerializablePredicateList | Waiting to access the list of predicate locks held by serializable transactions. |
SerializableXactHash | Waiting to read or update information about serializable transactions. |
SerialSLRU | Waiting to access the serializable transaction conflict SLRU cache. |
SharedTidBitmap | Waiting to access a shared TID bitmap during a parallel bitmap index scan. |
SharedTupleStore | Waiting to access a shared tuple store during parallel query. |
ShmemIndex | Waiting to find or allocate space in shared memory. |
SInvalRead | Waiting to retrieve messages from the shared catalog invalidation queue. |
SInvalWrite | Waiting to add a message to the shared catalog invalidation queue. |
SubtransBuffer | Waiting for I/O on a sub-transaction SLRU buffer. |
SubtransSLRU | Waiting to access the sub-transaction SLRU cache. |
SyncRep | Waiting to read or update information about the state of synchronous replication. |
SyncScan | Waiting to select the starting location of a synchronized table scan. |
TablespaceCreate | Waiting to create or drop a tablespace. |
TwoPhaseState | Waiting to read or update the state of prepared transactions. |
WALBufMapping | Waiting to replace a page in WAL buffers. |
WALInsert | Waiting to insert WAL data into a memory buffer. |
WALWrite | Waiting for WAL buffers to be written to disk. |
WrapLimitsVacuum | Waiting to update limits on transaction id and multixact consumption. |
XactBuffer | Waiting for I/O on a transaction status SLRU buffer. |
XactSLRU | Waiting to access the transaction status SLRU cache. |
XactTruncation | Waiting to execute pg_xact_status or update
the oldest transaction ID available to it. |
XidGen | Waiting to allocate a new transaction ID. |
Extensions can add LWLock
types to the list shown in
Table 28.12. In some cases, the name
assigned by an extension will not be available in all server processes;
so an LWLock
wait event might be reported as
just “extension
” rather than the
extension-assigned name.
Table 28.13. Wait Events of Type Timeout
Timeout Wait Event | Description |
---|---|
BaseBackupThrottle | Waiting during base backup when throttling activity. |
CheckpointWriteDelay | Waiting between writes while performing a checkpoint. |
PgSleep | Waiting due to a call to pg_sleep or
a sibling function. |
RecoveryApplyDelay | Waiting to apply WAL during recovery because of a delay setting. |
RecoveryRetrieveRetryInterval | Waiting during recovery when WAL data is not available from any
source (pg_wal , archive or stream). |
RegisterSyncRequest | Waiting while sending synchronization requests to the checkpointer, because the request queue is full. |
SpinDelay | Waiting while acquiring a contended spinlock. |
VacuumDelay | Waiting in a cost-based vacuum delay point. |
VacuumTruncate | Waiting to acquire an exclusive lock to truncate off any empty pages at the end of a table vacuumed. |
Here is an example of how wait events can be viewed:
SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event is NOT NULL; pid | wait_event_type | wait_event ------+-----------------+------------ 2540 | Lock | relation 6644 | LWLock | ProcArray (2 rows)
pg_stat_replication
#
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 28.14. pg_stat_replication
View
Column Type Description |
---|
Process ID of a WAL sender process |
OID of the user logged into this WAL sender process |
Name of the user logged into this WAL sender process |
Name of the application that is connected to this WAL sender |
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. |
Host name of the connected client, as reported by a
reverse DNS lookup of |
TCP port number that the client is using for communication
with this WAL sender, or |
Time when this process was started, i.e., when the client connected to this WAL sender |
This standby's |
Current WAL sender state. Possible values are:
|
Last write-ahead log location sent on this connection |
Last write-ahead log location written to disk by this standby server |
Last write-ahead log location flushed to disk by this standby server |
Last write-ahead log location replayed into the database on this standby server |
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
|
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
|
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
|
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. |
Synchronous state of this standby server. Possible values are:
|
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.
pg_stat_replication_slots
#
The pg_stat_replication_slots
view will contain
one row per logical replication slot, showing statistics about its usage.
Table 28.15. pg_stat_replication_slots
View
Column Type Description |
---|
A unique, cluster-wide identifier for the replication slot |
Number of transactions spilled to disk once the memory used by
logical decoding to decode changes from WAL has exceeded
|
Number of times transactions were spilled to disk while decoding changes from WAL for this slot. This counter is incremented each time a transaction is spilled, and the same transaction may be spilled multiple times. |
Amount of decoded transaction data spilled to disk while performing
decoding of changes from WAL for this slot. This and other spill
counters can be used to gauge the I/O which occurred during logical
decoding and allow tuning |
Number of in-progress transactions streamed to the decoding output
plugin after the memory used by logical decoding to decode changes
from WAL for this slot has exceeded
|
Number of times in-progress transactions were streamed to the decoding output plugin while decoding changes from WAL for this slot. This counter is incremented each time a transaction is streamed, and the same transaction may be streamed multiple times. |
Amount of transaction data decoded for streaming in-progress
transactions to the decoding output plugin while decoding changes from
WAL for this slot. This and other streaming counters for this slot can
be used to tune |
Number of decoded transactions sent to the decoding output plugin for this slot. This counts top-level transactions only, and is not incremented for subtransactions. Note that this includes the transactions that are streamed and/or spilled. |
Amount of transaction data decoded for sending transactions to the decoding output plugin while decoding changes from WAL for this slot. Note that this includes data that is streamed and/or spilled. |
Time at which these statistics were last reset |
pg_stat_wal_receiver
#
The pg_stat_wal_receiver
view will contain only
one row, showing statistics about the WAL receiver from that receiver's
connected server.
Table 28.16. pg_stat_wal_receiver
View
Column Type Description |
---|
Process ID of the WAL receiver process |
Activity status of the WAL receiver process |
First write-ahead log location used when WAL receiver is started |
First timeline number used when WAL receiver is started |
Last write-ahead log location already received and written to disk, but not flushed. This should not be used for data integrity checks. |
Last write-ahead log location already received and flushed to disk, the initial value of this field being the first log location used when WAL receiver is started |
Timeline number of last write-ahead log location received and flushed to disk, the initial value of this field being the timeline number of the first log location used when WAL receiver is started |
Send time of last message received from origin WAL sender |
Receipt time of last message received from origin WAL sender |
Last write-ahead log location reported to origin WAL sender |
Time of last write-ahead log location reported to origin WAL sender |
Replication slot name used by this WAL receiver |
Host of the PostgreSQL instance
this WAL receiver is connected to. This can be a host name,
an IP address, or a directory path if the connection is via
Unix socket. (The path case can be distinguished because it
will always be an absolute path, beginning with |
Port number of the PostgreSQL instance this WAL receiver is connected to. |
Connection string used by this WAL receiver, with security-sensitive fields obfuscated. |
pg_stat_recovery_prefetch
#
The pg_stat_recovery_prefetch
view will contain
only one row. The columns wal_distance
,
block_distance
and
io_depth
show current values, and the
other columns show cumulative counters that can be reset
with the pg_stat_reset_shared
function.
Table 28.17. pg_stat_recovery_prefetch
View
Column Type Description |
---|
Time at which these statistics were last reset |
Number of blocks prefetched because they were not in the buffer pool |
Number of blocks not prefetched because they were already in the buffer pool |
Number of blocks not prefetched because they would be zero-initialized |
Number of blocks not prefetched because they didn't exist yet |
Number of blocks not prefetched because a full page image was included in the WAL |
Number of blocks not prefetched because they were already recently prefetched |
How many bytes ahead the prefetcher is looking |
How many blocks ahead the prefetcher is looking |
How many prefetches have been initiated but are not yet known to have completed |
pg_stat_subscription
#Table 28.18. pg_stat_subscription
View
Column Type Description |
---|
OID of the subscription |
Name of the subscription |
Process ID of the subscription worker process |
Process ID of the leader apply worker if this process is a parallel apply worker; NULL if this process is a leader apply worker or a synchronization worker |
OID of the relation that the worker is synchronizing; NULL for the leader apply worker and parallel apply workers |
Last write-ahead log location received, the initial value of this field being 0; NULL for parallel apply workers |
Send time of last message received from origin WAL sender; NULL for parallel apply workers |
Receipt time of last message received from origin WAL sender; NULL for parallel apply workers |
Last write-ahead log location reported to origin WAL sender; NULL for parallel apply workers |
Time of last write-ahead log location reported to origin WAL sender; NULL for parallel apply workers |
pg_stat_subscription_stats
#
The pg_stat_subscription_stats
view will contain
one row per subscription.
Table 28.19. pg_stat_subscription_stats
View
Column Type Description |
---|
OID of the subscription |
Name of the subscription |
Number of times an error occurred while applying changes |
Number of times an error occurred during the initial table synchronization |
Time at which these statistics were last reset |
pg_stat_ssl
#
The pg_stat_ssl
view will contain one row per
backend or WAL sender process, showing statistics about SSL usage on
this connection. It can be joined to pg_stat_activity
or pg_stat_replication
on the
pid
column to get more details about the
connection.
Table 28.20. pg_stat_ssl
View
Column Type Description |
---|
Process ID of a backend or WAL sender process |
True if SSL is used on this connection |
Version of SSL in use, or NULL if SSL is not in use on this connection |
Name of SSL cipher in use, or NULL if SSL is not in use on this connection |
Number of bits in the encryption algorithm used, or NULL if SSL is not used on this connection |
Distinguished Name (DN) field from the client certificate
used, or NULL if no client certificate was supplied or if SSL
is not in use on this connection. This field is truncated if the
DN field is longer than |
Serial number of the client certificate, or NULL if no client certificate was supplied or if SSL is not in use on this connection. The combination of certificate serial number and certificate issuer uniquely identifies a certificate (unless the issuer erroneously reuses serial numbers). |
DN of the issuer of the client certificate, or NULL if no client
certificate was supplied or if SSL is not in use on this connection.
This field is truncated like |
pg_stat_gssapi
#
The pg_stat_gssapi
view will contain one row per
backend, showing information about GSSAPI usage on this connection. It can
be joined to pg_stat_activity
or
pg_stat_replication
on the
pid
column to get more details about the
connection.
Table 28.21. pg_stat_gssapi
View
Column Type Description |
---|
Process ID of a backend |
True if GSSAPI authentication was used for this connection |
Principal used to authenticate this connection, or NULL
if GSSAPI was not used to authenticate this connection. This
field is truncated if the principal is longer than
|
True if GSSAPI encryption is in use on this connection |
True if GSSAPI credentials were delegated on this connection. |
pg_stat_archiver
#
The pg_stat_archiver
view will always have a
single row, containing data about the archiver process of the cluster.
Table 28.22. pg_stat_archiver
View
Column Type Description |
---|
Number of WAL files that have been successfully archived |
Name of the WAL file most recently successfully archived |
Time of the most recent successful archive operation |
Number of failed attempts for archiving WAL files |
Name of the WAL file of the most recent failed archival operation |
Time of the most recent failed archival operation |
Time at which these statistics were last reset |
Normally, WAL files are archived in order, oldest to newest, but that is
not guaranteed, and does not hold under special circumstances like when
promoting a standby or after crash recovery. Therefore it is not safe to
assume that all files older than
last_archived_wal
have also been successfully
archived.
pg_stat_io
#
The pg_stat_io
view will contain one row for each
combination of backend type, target I/O object, and I/O context, showing
cluster-wide I/O statistics. Combinations which do not make sense are
omitted.
Currently, I/O on relations (e.g. tables, indexes) is tracked. However, relation I/O which bypasses shared buffers (e.g. when moving a table from one tablespace to another) is currently not tracked.
Table 28.23. pg_stat_io
View
Column Type Description |
---|
Type of backend (e.g. background worker, autovacuum worker). See
|
Target object of an I/O operation. Possible values are:
|
The context of an I/O operation. Possible values are:
|
Number of read operations, each of the size specified in
|
Time spent in read operations in milliseconds (if track_io_timing is enabled, otherwise zero) |
Number of write operations, each of the size specified in
|
Time spent in write operations in milliseconds (if track_io_timing is enabled, otherwise zero) |
Number of units of size |
Time spent in writeback operations in milliseconds (if track_io_timing is enabled, otherwise zero). This includes the time spent queueing write-out requests and, potentially, the time spent to write out the dirty data. |
Number of relation extend operations, each of the size specified in
|
Time spent in extend operations in milliseconds (if track_io_timing is enabled, otherwise zero) |
The number of bytes per unit of I/O read, written, or extended.
Relation data reads, writes, and extends are done in
|
The number of times a desired block was found in a shared buffer. |
Number of times a block has been written out from a shared or local buffer in order to make it available for another use.
In |
The number of times an existing buffer in a size-limited ring buffer
outside of shared buffers was reused as part of an I/O operation in the
|
Number of |
Time spent in fsync operations in milliseconds (if track_io_timing is enabled, otherwise zero) |
Time at which these statistics were last reset. |
Some backend types never perform I/O operations on some I/O objects and/or
in some I/O contexts. These rows are omitted from the view. For example, the
checkpointer does not checkpoint temporary tables, so there will be no rows
for backend_type
checkpointer
and
object
temp relation
.
In addition, some I/O operations will never be performed either by certain
backend types or on certain I/O objects and/or in certain I/O contexts.
These cells will be NULL. For example, temporary tables are not
fsync
ed, so fsyncs
will be NULL for
object
temp relation
. Also, the
background writer does not perform reads, so reads
will
be NULL in rows for backend_type
background
writer
.
pg_stat_io
can be used to inform database tuning.
For example:
A high evictions
count can indicate that shared
buffers should be increased.
Client backends rely on the checkpointer to ensure data is persisted to
permanent storage. Large numbers of fsyncs
by
client backend
s could indicate a misconfiguration of
shared buffers or of the checkpointer. More information on configuring
the checkpointer can be found in Section 30.5.
Normally, client backends should be able to rely on auxiliary processes like the checkpointer and the background writer to write out dirty data as much as possible. Large numbers of writes by client backends could indicate a misconfiguration of shared buffers or of the checkpointer. More information on configuring the checkpointer can be found in Section 30.5.
Columns tracking I/O time will only be non-zero when
track_io_timing is enabled. The user should be
careful when referencing these columns in combination with their
corresponding IO operations in case track_io_timing
was not enabled for the entire time since the last stats reset.
pg_stat_bgwriter
#
The pg_stat_bgwriter
view will always have a
single row, containing global data for the cluster.
Table 28.24. pg_stat_bgwriter
View
Column Type Description |
---|
Number of scheduled checkpoints that have been performed |
Number of requested checkpoints that have been performed |
Total amount of time that has been spent in the portion of checkpoint processing where files are written to disk, in milliseconds |
Total amount of time that has been spent in the portion of checkpoint processing where files are synchronized to disk, in milliseconds |
Number of buffers written during checkpoints |
Number of buffers written by the background writer |
Number of times the background writer stopped a cleaning scan because it had written too many buffers |
Number of buffers written directly by a backend |
Number of times a backend had to execute its own
|
Number of buffers allocated |
Time at which these statistics were last reset |
pg_stat_wal
#
The pg_stat_wal
view will always have a
single row, containing data about WAL activity of the cluster.
Table 28.25. pg_stat_wal
View
Column Type Description |
---|
Total number of WAL records generated |
Total number of WAL full page images generated |
Total amount of WAL generated in bytes |
Number of times WAL data was written to disk because WAL buffers became full |
Number of times WAL buffers were written out to disk via
|
Number of times WAL files were synced to disk via
|
Total amount of time spent writing WAL buffers to disk via
|
Total amount of time spent syncing WAL files to disk via
|
Time at which these statistics were last reset |
pg_stat_database
#
The pg_stat_database
view will contain one row
for each database in the cluster, plus one for shared objects, showing
database-wide statistics.
Table 28.26. pg_stat_database
View
Column Type Description |
---|
OID of this database, or 0 for objects belonging to a shared relation |
Name of this database, or |
Number of backends currently connected to this database, or
|
Number of transactions in this database that have been committed |
Number of transactions in this database that have been rolled back |
Number of disk blocks read in this database |
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) |
Number of live rows fetched by sequential scans and index entries returned by index scans in this database |
Number of live rows fetched by index scans in this database |
Number of rows inserted by queries in this database |
Number of rows updated by queries in this database |
Number of rows deleted by queries in this database |
Number of queries canceled due to conflicts with recovery
in this database. (Conflicts occur only on standby servers; see
|
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. |
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. |
Number of deadlocks detected in this database |
Number of data page checksum failures detected in this database (or on a shared object), or NULL if data checksums are not enabled. |
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. |
Time spent reading data file blocks by backends in this database, in milliseconds (if track_io_timing is enabled, otherwise zero) |
Time spent writing data file blocks by backends in this database, in milliseconds (if track_io_timing is enabled, otherwise zero) |
Time spent by database sessions in this database, in milliseconds (note that statistics are only updated when the state of a session changes, so if sessions have been idle for a long time, this idle time won't be included) |
Time spent executing SQL statements in this database, in milliseconds
(this corresponds to the states |
Time spent idling while in a transaction in this database, in milliseconds
(this corresponds to the states |
Total number of sessions established to this database |
Number of database sessions to this database that were terminated because connection to the client was lost |
Number of database sessions to this database that were terminated by fatal errors |
Number of database sessions to this database that were terminated by operator intervention |
Time at which these statistics were last reset |
pg_stat_database_conflicts
#
The pg_stat_database_conflicts
view will contain
one row per database, showing database-wide statistics about
query cancels occurring due to conflicts with recovery on standby servers.
This view will only contain information on standby servers, since
conflicts do not occur on primary servers.
Table 28.27. pg_stat_database_conflicts
View
Column Type Description |
---|
OID of a database |
Name of this database |
Number of queries in this database that have been canceled due to dropped tablespaces |
Number of queries in this database that have been canceled due to lock timeouts |
Number of queries in this database that have been canceled due to old snapshots |
Number of queries in this database that have been canceled due to pinned buffers |
Number of queries in this database that have been canceled due to deadlocks |
Number of uses of logical slots in this database that have been canceled due to old snapshots or too low a wal_level on the primary |
pg_stat_all_tables
#
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 28.28. pg_stat_all_tables
View
Column Type Description |
---|
OID of a table |
Name of the schema that this table is in |
Name of this table |
Number of sequential scans initiated on this table |
The time of the last sequential scan on this table, based on the most recent transaction stop time |
Number of live rows fetched by sequential scans |
Number of index scans initiated on this table |
The time of the last index scan on this table, based on the most recent transaction stop time |
Number of live rows fetched by index scans |
Total number of rows inserted |
Total number of rows updated. (This includes row updates
counted in |
Total number of rows deleted |
Number of rows HOT updated. These are updates where no successor versions are required in indexes. |
Number of rows updated where the successor version goes onto a
new heap page, leaving behind an original
version with a
|
Estimated number of live rows |
Estimated number of dead rows |
Estimated number of rows modified since this table was last analyzed |
Estimated number of rows inserted since this table was last vacuumed |
Last time at which this table was manually vacuumed
(not counting |
Last time at which this table was vacuumed by the autovacuum daemon |
Last time at which this table was manually analyzed |
Last time at which this table was analyzed by the autovacuum daemon |
Number of times this table has been manually vacuumed
(not counting |
Number of times this table has been vacuumed by the autovacuum daemon |
Number of times this table has been manually analyzed |
Number of times this table has been analyzed by the autovacuum daemon |
pg_stat_all_indexes
#
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 28.29. pg_stat_all_indexes
View
Column Type Description |
---|
OID of the table for this index |
OID of this index |
Name of the schema this index is in |
Name of the table for this index |
Name of this index |
Number of index scans initiated on this index |
The time of the last scan on this index, based on the most recent transaction stop time |
Number of index entries returned by scans on this index |
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.
The idx_tup_read
and idx_tup_fetch
counts
can be different even without any use of 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, or if any
heap fetches are avoided by means of an index-only scan.
pg_statio_all_tables
#
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 28.30. pg_statio_all_tables
View
Column Type Description |
---|
OID of a table |
Name of the schema that this table is in |
Name of this table |
Number of disk blocks read from this table |
Number of buffer hits in this table |
Number of disk blocks read from all indexes on this table |
Number of buffer hits in all indexes on this table |
Number of disk blocks read from this table's TOAST table (if any) |
Number of buffer hits in this table's TOAST table (if any) |
Number of disk blocks read from this table's TOAST table indexes (if any) |
Number of buffer hits in this table's TOAST table indexes (if any) |
pg_statio_all_indexes
#
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 28.31. pg_statio_all_indexes
View
Column Type Description |
---|
OID of the table for this index |
OID of this index |
Name of the schema this index is in |
Name of the table for this index |
Name of this index |
Number of disk blocks read from this index |
Number of buffer hits in this index |
pg_statio_all_sequences
#
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 28.32. pg_statio_all_sequences
View
Column Type Description |
---|
OID of a sequence |
Name of the schema this sequence is in |
Name of this sequence |
Number of disk blocks read from this sequence |
Number of buffer hits in this sequence |
pg_stat_user_functions
#
The pg_stat_user_functions
view will contain
one row for each tracked function, showing statistics about executions of
that function. The track_functions parameter
controls exactly which functions are tracked.
Table 28.33. pg_stat_user_functions
View
Column Type Description |
---|
OID of a function |
Name of the schema this function is in |
Name of this function |
Number of times this function has been called |
Total time spent in this function and all other functions called by it, in milliseconds |
Total time spent in this function itself, not including other functions called by it, in milliseconds |
pg_stat_slru
#
PostgreSQL accesses certain on-disk information
via SLRU (simple least-recently-used) caches.
The pg_stat_slru
view will contain
one row for each tracked SLRU cache, showing statistics about access
to cached pages.
Table 28.34. pg_stat_slru
View
Column Type Description |
---|
Name of the SLRU |
Number of blocks zeroed during initializations |
Number of times disk blocks were found already in the SLRU, so that a read was not necessary (this only includes hits in the SLRU, not the operating system's file system cache) |
Number of disk blocks read for this SLRU |
Number of disk blocks written for this SLRU |
Number of blocks checked for existence for this SLRU |
Number of flushes of dirty data for this SLRU |
Number of truncates for this SLRU |
Time at which these statistics were last reset |
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 the cumulative statistics system are listed in Table 28.35.
Table 28.35. Additional Statistics Functions
Using pg_stat_reset()
also resets counters that
autovacuum uses to determine when to trigger a vacuum or an analyze.
Resetting these counters can cause autovacuum to not perform necessary
work, which can cause problems such as table bloat or out-dated
table statistics. A database-wide ANALYZE
is
recommended after the statistics have been reset.
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, another set of per-backend statistics
access functions can be used; these are shown in Table 28.36.
These access functions use the session's backend ID number, which is a
small positive integer that is distinct from the backend ID of any
concurrent session, although a session's ID can be recycled as soon as
it exits. The backend ID is used, among other things, to identify the
session's temporary schema if it has one.
The function pg_stat_get_backend_idset
provides a
convenient way to list all the active backends' ID numbers for
invoking these functions. For example, to show the PIDs and
current queries of all backends:
SELECT pg_stat_get_backend_pid(backendid) AS pid, pg_stat_get_backend_activity(backendid) AS query FROM pg_stat_get_backend_idset() AS backendid;
Table 28.36. Per-Backend Statistics Functions
Function Description |
---|
Returns the text of this backend's most recent query. |
Returns the time when the backend's most recent query was started. |
Returns the IP address of the client connected to this backend. |
Returns the TCP port number that the client is using for communication. |
Returns the OID of the database this backend is connected to. |
Returns the set of currently active backend ID numbers. |
Returns the process ID of this backend. |
Returns the time when this process was started. |
Returns a record of information about the subtransactions of the
backend with the specified ID.
The fields returned are |
Returns the OID of the user logged into this backend. |
Returns the wait event name if this backend is currently waiting, otherwise NULL. See Table 28.5 through Table 28.13. |
Returns the wait event type name if this backend is currently waiting, otherwise NULL. See Table 28.4 for details. |
Returns the time when the backend's current transaction was started. |