Monitoring Database Activitymonitoringdatabase activitydatabase activitymonitoring
A database administrator frequently wonders, What is the system
doing right now?
This chapter discusses how to find that out.
Several tools are available for monitoring database activity and
analyzing performance. Most of this chapter is devoted to describing
PostgreSQL's statistics collector,
but one should not neglect regular Unix monitoring programs such as
ps, top, iostat, and vmstat.
Also, once one has identified a
poorly-performing query, further investigation might be needed using
PostgreSQL's command.
discusses EXPLAIN
and other methods for understanding the behavior of an individual
query.
Standard Unix Toolspsto monitor activity
On most Unix platforms, PostgreSQL modifies its
command title as reported by ps, so that individual server
processes can readily be identified. A sample display is
$ ps auxww | grep ^postgres
postgres 15551 0.0 0.1 57536 7132 pts/0 S 18:02 0:00 postgres -i
postgres 15554 0.0 0.0 57536 1184 ? Ss 18:02 0:00 postgres: background writer
postgres 15555 0.0 0.0 57536 916 ? Ss 18:02 0:00 postgres: checkpointer
postgres 15556 0.0 0.0 57536 916 ? Ss 18:02 0:00 postgres: walwriter
postgres 15557 0.0 0.0 58504 2244 ? Ss 18:02 0:00 postgres: autovacuum launcher
postgres 15558 0.0 0.0 17512 1068 ? Ss 18:02 0:00 postgres: stats collector
postgres 15582 0.0 0.0 58772 3080 ? Ss 18:04 0:00 postgres: joe runbug 127.0.0.1 idle
postgres 15606 0.0 0.0 58772 3052 ? Ss 18:07 0:00 postgres: tgl regression [local] SELECT waiting
postgres 15610 0.0 0.0 58772 3056 ? Ss 18:07 0:00 postgres: tgl regression [local] idle in transaction
(The appropriate invocation of ps varies across different
platforms, as do the details of what is shown. This example is from a
recent Linux system.) The first process listed here is the
master server process. The command arguments
shown for it are the same ones used when it was launched. The next five
processes are background worker processes automatically launched by the
master process. (The stats collector process will not be present
if you have set the system not to start the statistics collector; likewise
the autovacuum launcher process can be disabled.)
Each of the remaining
processes is a server process handling one client connection. Each such
process sets its command line display in the form
postgres: userdatabasehostactivity
The user, database, and (client) host items remain the same for
the life of the client connection, but the activity indicator changes.
The activity can be idle (i.e., waiting for a client command),
idle in transaction (waiting for client inside a BEGIN block),
or a command type name such as SELECT. Also,
waiting is appended if the server process is presently waiting
on a lock held by another session. In the above example we can infer
that process 15606 is waiting for process 15610 to complete its transaction
and thereby release some lock. (Process 15610 must be the blocker, because
there is no other active session. In more complicated cases it would be
necessary to look into the
pg_locks
system view to determine who is blocking whom.)
If has been configured the
cluster name will also be shown in ps output:
$ psql -c 'SHOW cluster_name'
cluster_name
--------------
server1
(1 row)
$ ps aux|grep server1
postgres 27093 0.0 0.0 30096 2752 ? Ss 11:34 0:00 postgres: server1: background writer
...
If you have turned off then the
activity indicator is not updated; the process title is set only once
when a new process is launched. On some platforms this saves a measurable
amount of per-command overhead; on others it's insignificant.
Solaris requires special handling. You must
use /usr/ucb/ps, rather than
/bin/ps. You also must use two
flags, not just one. In addition, your original invocation of the
postgres command must have a shorter
ps status display than that provided by each
server process. If you fail to do all three things, the ps
output for each server process will be the original postgres
command line.
The Statistics CollectorstatisticsPostgreSQL'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 vacuum and
analyze actions for each table. It can also count calls to user-defined
functions and the total time spent in each one.
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 collector process.
Statistics Collection Configuration
Since collection of statistics adds some overhead to query execution,
the system can be configured to collect or not collect information.
This is controlled by configuration parameters that are normally set in
postgresql.conf. (See for
details about setting configuration parameters.)
The parameter enables monitoring
of the current command being executed by any server process.
The parameter controls whether
statistics are collected about table and index accesses.
The parameter enables tracking of
usage of user-defined functions.
The parameter enables monitoring
of block read and 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 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
parameter,
pg_stat_tmp 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.
Viewing Statistics
Several predefined views, listed in , are available to show
the current state of the system. There are also several other
views, listed in , available to show the results
of statistics collection. Alternatively, one can
build custom views using the underlying statistics functions, as discussed
in .
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_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 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 ) can see all the information about all sessions.
Dynamic Statistics ViewsView NameDescriptionpg_stat_activitypg_stat_activity
One row per server process, showing information related to
the current activity of that process, such as state and current query.
See for details.
pg_stat_replicationpg_stat_replicationOne row per WAL sender process, showing statistics about
replication to that sender's connected standby server.
See for details.
pg_stat_wal_receiverpg_stat_wal_receiverOnly one row, showing statistics about the WAL receiver from
that receiver's connected server.
See for details.
pg_stat_subscriptionpg_stat_subscriptionAt least one row per subscription, showing information about
the subscription workers.
See for details.
pg_stat_sslpg_stat_sslOne row per connection (regular and replication), showing information about
SSL used on this connection.
See for details.
pg_stat_gssapipg_stat_gssapiOne row per connection (regular and replication), showing information about
GSSAPI authentication and encryption used on this connection.
See for details.
pg_stat_progress_create_indexpg_stat_progress_create_indexOne row for each backend running CREATE INDEX or REINDEX, showing
current progress.
See .
pg_stat_progress_vacuumpg_stat_progress_vacuumOne row for each backend (including autovacuum worker processes) running
VACUUM, showing current progress.
See .
pg_stat_progress_clusterpg_stat_progress_clusterOne row for each backend running
CLUSTER or VACUUM FULL, showing current progress.
See .
Collected Statistics ViewsView NameDescriptionpg_stat_archiverpg_stat_archiverOne row only, showing statistics about the
WAL archiver process's activity. See
for details.
pg_stat_bgwriterpg_stat_bgwriterOne row only, showing statistics about the
background writer process's activity. See
for details.
pg_stat_databasepg_stat_databaseOne row per database, showing database-wide statistics. See
for details.
pg_stat_database_conflictspg_stat_database_conflicts
One row per database, showing database-wide statistics about
query cancels due to conflict with recovery on standby servers.
See for details.
pg_stat_all_tablespg_stat_all_tables
One row for each table in the current database, showing statistics
about accesses to that specific table.
See for details.
pg_stat_sys_tablespg_stat_sys_tablesSame as pg_stat_all_tables, except that only
system tables are shown.pg_stat_user_tablespg_stat_user_tablesSame as pg_stat_all_tables, except that only user
tables are shown.pg_stat_xact_all_tablespg_stat_xact_all_tablesSimilar 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_tablespg_stat_xact_sys_tablesSame as pg_stat_xact_all_tables, except that only
system tables are shown.pg_stat_xact_user_tablespg_stat_xact_user_tablesSame as pg_stat_xact_all_tables, except that only
user tables are shown.pg_stat_all_indexespg_stat_all_indexes
One row for each index in the current database, showing statistics
about accesses to that specific index.
See for details.
pg_stat_sys_indexespg_stat_sys_indexesSame as pg_stat_all_indexes, except that only
indexes on system tables are shown.pg_stat_user_indexespg_stat_user_indexesSame as pg_stat_all_indexes, except that only
indexes on user tables are shown.pg_statio_all_tablespg_statio_all_tables
One row for each table in the current database, showing statistics
about I/O on that specific table.
See for details.
pg_statio_sys_tablespg_statio_sys_tablesSame as pg_statio_all_tables, except that only
system tables are shown.pg_statio_user_tablespg_statio_user_tablesSame as pg_statio_all_tables, except that only
user tables are shown.pg_statio_all_indexespg_statio_all_indexes
One row for each index in the current database,
showing statistics about I/O on that specific index.
See for details.
pg_statio_sys_indexespg_statio_sys_indexesSame as pg_statio_all_indexes, except that only
indexes on system tables are shown.pg_statio_user_indexespg_statio_user_indexesSame as pg_statio_all_indexes, except that only
indexes on user tables are shown.pg_statio_all_sequencespg_statio_all_sequences
One row for each sequence in the current database,
showing statistics about I/O on that specific sequence.
See for details.
pg_statio_sys_sequencespg_statio_sys_sequencesSame as pg_statio_all_sequences, except that only
system sequences are shown. (Presently, no system sequences are defined,
so this view is always empty.)pg_statio_user_sequencespg_statio_user_sequencesSame as pg_statio_all_sequences, except that only
user sequences are shown.pg_stat_user_functionspg_stat_user_functions
One row for each tracked function, showing statistics
about executions of that function. See
for details.
pg_stat_xact_user_functionspg_stat_xact_user_functionsSimilar to pg_stat_user_functions, but counts only
calls during the current transaction (which are not
yet included in pg_stat_user_functions).
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.
pg_stat_activity ViewColumnTypeDescriptiondatidoidOID of the database this backend is connected todatnamenameName of the database this backend is connected topidintegerProcess ID of this backendusesysidoidOID of the user logged into this backendusenamenameName of the user logged into this backendapplication_nametextName of the application that is connected
to this backendclient_addrinetIP 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.
client_hostnametextHost 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 is enabled.
client_portintegerTCP port number that the client is using for communication
with this backend, or -1 if a Unix socket is used.
If this field is null, it indicates that this is an internal server process.
backend_starttimestamp with time zoneTime when this process was started. For client backends,
this is the time the client connected to the server.
xact_starttimestamp with time zoneTime 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_starttimestamp with time zoneTime when the currently active query was started, or if
state is not active, when the last query
was started
state_changetimestamp with time zoneTime when the state was last changedwait_event_typetextThe type of event for which the backend is waiting, if any;
otherwise NULL. Possible values are:
LWLock: The backend is waiting for a lightweight lock.
Each such lock protects 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.)
Lock: The backend 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.
BufferPin: The server process is waiting to access to
a data buffer during a period when no other process can be
examining that buffer. Buffer pin waits can be protracted if
another process holds an open cursor which last read data from the
buffer in question.
Activity: The server process is idle. This is used by
system processes waiting for activity in their main processing loop.
wait_event will identify the specific wait point.
Extension: The server process is waiting for activity
in an extension module. This category is useful for modules to
track custom waiting points.
Client: The server process is waiting for some activity
on a socket from user applications, and that the server expects
something to happen that is independent from its internal processes.
wait_event will identify the specific wait point.
IPC: The server process is waiting for some activity
from another process in the server. wait_event will
identify the specific wait point.
Timeout: The server process is waiting for a timeout
to expire. wait_event will identify the specific wait
point.
IO: The server process is waiting for a IO to complete.
wait_event will identify the specific wait point.
wait_eventtextWait event name if backend is currently waiting, otherwise NULL.
See for details.
statetextCurrent 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 is disabled in this backend.
backend_xidxidTop-level transaction identifier of this backend, if any.backend_xminxidThe current backend's xmin horizon.querytextText 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
characters; this value can be changed via the parameter
.
backend_typetextType of current backend. Possible types are
autovacuum launcher, autovacuum 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.
The pg_stat_activity view will have one row
per server process, showing information related to
the current activity of that process.
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.
wait_event DescriptionWait Event TypeWait Event NameDescriptionLWLockShmemIndexLockWaiting to find or allocate space in shared memory.OidGenLockWaiting to allocate or assign an OID.XidGenLockWaiting to allocate or assign a transaction id.ProcArrayLockWaiting to get a snapshot or clearing a transaction id at
transaction end.SInvalReadLockWaiting to retrieve or remove messages from shared invalidation
queue.SInvalWriteLockWaiting to add a message in shared invalidation queue.WALBufMappingLockWaiting to replace a page in WAL buffers.WALWriteLockWaiting for WAL buffers to be written to disk.ControlFileLockWaiting to read or update the control file or creation of a
new WAL file.CheckpointLockWaiting to perform checkpoint.CLogControlLockWaiting to read or update transaction status.SubtransControlLockWaiting to read or update sub-transaction information.MultiXactGenLockWaiting to read or update shared multixact state.MultiXactOffsetControlLockWaiting to read or update multixact offset mappings.MultiXactMemberControlLockWaiting to read or update multixact member mappings.RelCacheInitLockWaiting to read or write relation cache initialization
file.CheckpointerCommLockWaiting to manage fsync requests.TwoPhaseStateLockWaiting to read or update the state of prepared transactions.TablespaceCreateLockWaiting to create or drop the tablespace.BtreeVacuumLockWaiting to read or update vacuum-related information for a
B-tree index.AddinShmemInitLockWaiting to manage space allocation in shared memory.AutovacuumLockAutovacuum worker or launcher waiting to update or
read the current state of autovacuum workers.AutovacuumScheduleLockWaiting to ensure that the table it has selected for a vacuum
still needs vacuuming.
SyncScanLockWaiting to get the start location of a scan on a table for
synchronized scans.RelationMappingLockWaiting to update the relation map file used to store catalog
to filenode mapping.
AsyncCtlLockWaiting to read or update shared notification state.AsyncQueueLockWaiting to read or update notification messages.SerializableXactHashLockWaiting to retrieve or store information about serializable
transactions.SerializableFinishedListLockWaiting to access the list of finished serializable
transactions.SerializablePredicateLockListLockWaiting to perform an operation on a list of locks held by
serializable transactions.OldSerXidLockWaiting to read or record conflicting serializable
transactions.SyncRepLockWaiting to read or update information about synchronous
replicas.BackgroundWorkerLockWaiting to read or update background worker state.DynamicSharedMemoryControlLockWaiting to read or update dynamic shared memory state.AutoFileLockWaiting to update the postgresql.auto.conf file.ReplicationSlotAllocationLockWaiting to allocate or free a replication slot.ReplicationSlotControlLockWaiting to read or update replication slot state.CommitTsControlLockWaiting to read or update transaction commit timestamps.CommitTsLockWaiting to read or update the last value set for the
transaction timestamp.ReplicationOriginLockWaiting to setup, drop or use replication origin.MultiXactTruncationLockWaiting to read or truncate multixact information.OldSnapshotTimeMapLockWaiting to read or update old snapshot control information.LogicalRepWorkerLockWaiting for action on logical replication worker to finish.CLogTruncationLockWaiting to execute txid_status or update
the oldest transaction id available to it.clogWaiting for I/O on a clog (transaction status) buffer.commit_timestampWaiting for I/O on commit timestamp buffer.subtransWaiting for I/O a subtransaction buffer.multixact_offsetWaiting for I/O on a multixact offset buffer.multixact_memberWaiting for I/O on a multixact_member buffer.asyncWaiting for I/O on an async (notify) buffer.oldserxidWaiting for I/O on an oldserxid buffer.wal_insertWaiting to insert WAL into a memory buffer.buffer_contentWaiting to read or write a data page in memory.buffer_ioWaiting for I/O on a data page.replication_originWaiting to read or update the replication progress.replication_slot_ioWaiting for I/O on a replication slot.procWaiting to read or update the fast-path lock information.buffer_mappingWaiting to associate a data block with a buffer in the buffer
pool.lock_managerWaiting to add or examine locks for backends, or waiting to
join or exit a locking group (used by parallel query).predicate_lock_managerWaiting to add or examine predicate lock information.serializable_xactWaiting to perform an operation on a serializable transaction
in a parallel query.parallel_query_dsaWaiting for parallel query dynamic shared memory allocation lock.tbmWaiting for TBM shared iterator lock.parallel_appendWaiting to choose the next subplan during Parallel Append plan
execution.parallel_hash_joinWaiting to allocate or exchange a chunk of memory or update
counters during Parallel Hash plan execution.LockrelationWaiting to acquire a lock on a relation.extendWaiting to extend a relation.pageWaiting to acquire a lock on page of a relation.tupleWaiting to acquire a lock on a tuple.transactionidWaiting for a transaction to finish.virtualxidWaiting to acquire a virtual xid lock.speculative tokenWaiting to acquire a speculative insertion lock.objectWaiting to acquire a lock on a non-relation database object.userlockWaiting to acquire a user lock.advisoryWaiting to acquire an advisory user lock.BufferPinBufferPinWaiting to acquire a pin on a buffer.ActivityArchiverMainWaiting in main loop of the archiver process.AutoVacuumMainWaiting in main loop of autovacuum launcher process.BgWriterHibernateWaiting in background writer process, hibernating.BgWriterMainWaiting in main loop of background writer process background worker.CheckpointerMainWaiting in main loop of checkpointer process.LogicalApplyMainWaiting in main loop of logical apply process.LogicalLauncherMainWaiting in main loop of logical launcher process.PgStatMainWaiting in main loop of the statistics collector process.RecoveryWalAllWaiting for WAL from any kind of source (local, archive or stream) at recovery.RecoveryWalStreamWaiting for WAL from a stream at recovery.SysLoggerMainWaiting in main loop of syslogger process.WalReceiverMainWaiting in main loop of WAL receiver process.WalSenderMainWaiting in main loop of WAL sender process.WalWriterMainWaiting in main loop of WAL writer process.ClientClientReadWaiting to read data from the client.ClientWriteWaiting to write data to the client.LibPQWalReceiverConnectWaiting in WAL receiver to establish connection to remote server.LibPQWalReceiverReceiveWaiting in WAL receiver to receive data from remote server.SSLOpenServerWaiting for SSL while attempting connection.WalReceiverWaitStartWaiting for startup process to send initial data for streaming replication.WalSenderWaitForWALWaiting for WAL to be flushed in WAL sender process.WalSenderWriteDataWaiting for any activity when processing replies from WAL receiver in WAL sender process.ExtensionExtensionWaiting in an extension.IPCBgWorkerShutdownWaiting for background worker to shut down.BgWorkerStartupWaiting for background worker to start up.BtreePageWaiting for the page number needed to continue a parallel B-tree scan to become available.CheckpointDoneWaiting for a checkpoint to complete.CheckpointStartWaiting for a checkpoint to start.ClogGroupUpdateWaiting for group leader to update transaction status at transaction end.ExecuteGatherWaiting for activity from child process when executing Gather node.Hash/Batch/AllocatingWaiting for an elected Parallel Hash participant to allocate a hash table.Hash/Batch/ElectingElecting a Parallel Hash participant to allocate a hash table.Hash/Batch/LoadingWaiting for other Parallel Hash participants to finish loading a hash table.Hash/Build/AllocatingWaiting for an elected Parallel Hash participant to allocate the initial hash table.Hash/Build/ElectingElecting a Parallel Hash participant to allocate the initial hash table.Hash/Build/HashingInnerWaiting for other Parallel Hash participants to finish hashing the inner relation.Hash/Build/HashingOuterWaiting for other Parallel Hash participants to finish partitioning the outer relation.Hash/GrowBatches/AllocatingWaiting for an elected Parallel Hash participant to allocate more batches.Hash/GrowBatches/DecidingElecting a Parallel Hash participant to decide on future batch growth.Hash/GrowBatches/ElectingElecting a Parallel Hash participant to allocate more batches.Hash/GrowBatches/FinishingWaiting for an elected Parallel Hash participant to decide on future batch growth.Hash/GrowBatches/RepartitioningWaiting for other Parallel Hash participants to finishing repartitioning.Hash/GrowBuckets/AllocatingWaiting for an elected Parallel Hash participant to finish allocating more buckets.Hash/GrowBuckets/ElectingElecting a Parallel Hash participant to allocate more buckets.Hash/GrowBuckets/ReinsertingWaiting for other Parallel Hash participants to finish inserting tuples into new buckets.LogicalSyncDataWaiting for logical replication remote server to send data for initial table synchronization.LogicalSyncStateChangeWaiting for logical replication remote server to change state.MessageQueueInternalWaiting for other process to be attached in shared message queue.MessageQueuePutMessageWaiting to write a protocol message to a shared message queue.MessageQueueReceiveWaiting to receive bytes from a shared message queue.MessageQueueSendWaiting to send bytes to a shared message queue.ParallelBitmapScanWaiting for parallel bitmap scan to become initialized.ParallelCreateIndexScanWaiting for parallel CREATE INDEX workers to finish heap scan.ParallelFinishWaiting for parallel workers to finish computing.ProcArrayGroupUpdateWaiting for group leader to clear transaction id at transaction end.PromoteWaiting for standby promotion.ReplicationOriginDropWaiting for a replication origin to become inactive to be dropped.ReplicationSlotDropWaiting for a replication slot to become inactive to be dropped.SafeSnapshotWaiting for a snapshot for a READ ONLY DEFERRABLE transaction.SyncRepWaiting for confirmation from remote server during synchronous replication.TimeoutBaseBackupThrottleWaiting during base backup when throttling activity.PgSleepWaiting in process that called pg_sleep.RecoveryApplyDelayWaiting to apply WAL at recovery because it is delayed.IOBufFileReadWaiting for a read from a buffered file.BufFileWriteWaiting for a write to a buffered file.ControlFileReadWaiting for a read from the control file.ControlFileSyncWaiting for the control file to reach stable storage.ControlFileSyncUpdateWaiting for an update to the control file to reach stable storage.ControlFileWriteWaiting for a write to the control file.ControlFileWriteUpdateWaiting for a write to update the control file.CopyFileReadWaiting for a read during a file copy operation.CopyFileWriteWaiting for a write during a file copy operation.DataFileExtendWaiting for a relation data file to be extended.DataFileFlushWaiting for a relation data file to reach stable storage.DataFileImmediateSyncWaiting for an immediate synchronization of a relation data file to stable storage.DataFilePrefetchWaiting for an asynchronous prefetch from a relation data file.DataFileReadWaiting for a read from a relation data file.DataFileSyncWaiting for changes to a relation data file to reach stable storage.DataFileTruncateWaiting for a relation data file to be truncated.DataFileWriteWaiting for a write to a relation data file.DSMFillZeroWriteWaiting to write zero bytes to a dynamic shared memory backing file.LockFileAddToDataDirReadWaiting for a read while adding a line to the data directory lock file.LockFileAddToDataDirSyncWaiting for data to reach stable storage while adding a line to the data directory lock file.LockFileAddToDataDirWriteWaiting for a write while adding a line to the data directory lock file.LockFileCreateReadWaiting to read while creating the data directory lock file.LockFileCreateSyncWaiting for data to reach stable storage while creating the data directory lock file.LockFileCreateWriteWaiting for a write while creating the data directory lock file.LockFileReCheckDataDirReadWaiting for a read during recheck of the data directory lock file.LogicalRewriteCheckpointSyncWaiting for logical rewrite mappings to reach stable storage during a checkpoint.LogicalRewriteMappingSyncWaiting for mapping data to reach stable storage during a logical rewrite.LogicalRewriteMappingWriteWaiting for a write of mapping data during a logical rewrite.LogicalRewriteSyncWaiting for logical rewrite mappings to reach stable storage.LogicalRewriteWriteWaiting for a write of logical rewrite mappings.ProcSignalBarrierWaiting for a barrier event to be processed by all backends.RelationMapReadWaiting for a read of the relation map file.RelationMapSyncWaiting for the relation map file to reach stable storage.RelationMapWriteWaiting for a write to the relation map file.ReorderBufferReadWaiting for a read during reorder buffer management.ReorderBufferWriteWaiting for a write during reorder buffer management.ReorderLogicalMappingReadWaiting for a read of a logical mapping during reorder buffer management.ReplicationSlotReadWaiting for a read from a replication slot control file.ReplicationSlotRestoreSyncWaiting for a replication slot control file to reach stable storage while restoring it to memory.ReplicationSlotSyncWaiting for a replication slot control file to reach stable storage.ReplicationSlotWriteWaiting for a write to a replication slot control file.SLRUFlushSyncWaiting for SLRU data to reach stable storage during a checkpoint or database shutdown.SLRUReadWaiting for a read of an SLRU page.SLRUSyncWaiting for SLRU data to reach stable storage following a page write.SLRUWriteWaiting for a write of an SLRU page.SnapbuildReadWaiting for a read of a serialized historical catalog snapshot.SnapbuildSyncWaiting for a serialized historical catalog snapshot to reach stable storage.SnapbuildWriteWaiting for a write of a serialized historical catalog snapshot.TimelineHistoryFileSyncWaiting for a timeline history file received via streaming replication to reach stable storage.TimelineHistoryFileWriteWaiting for a write of a timeline history file received via streaming replication.TimelineHistoryReadWaiting for a read of a timeline history file.TimelineHistorySyncWaiting for a newly created timeline history file to reach stable storage.TimelineHistoryWriteWaiting for a write of a newly created timeline history file.TwophaseFileReadWaiting for a read of a two phase state file.TwophaseFileSyncWaiting for a two phase state file to reach stable storage.TwophaseFileWriteWaiting for a write of a two phase state file.WALBootstrapSyncWaiting for WAL to reach stable storage during bootstrapping.WALBootstrapWriteWaiting for a write of a WAL page during bootstrapping.WALCopyReadWaiting for a read when creating a new WAL segment by copying an existing one.WALCopySyncWaiting a new WAL segment created by copying an existing one to reach stable storage.WALCopyWriteWaiting for a write when creating a new WAL segment by copying an existing one.WALInitSyncWaiting for a newly initialized WAL file to reach stable storage.WALInitWriteWaiting for a write while initializing a new WAL file.WALReadWaiting for a read from a WAL file.WALSenderTimelineHistoryReadWaiting for a read from a timeline history file during walsender timeline command.WALSyncWaiting for a WAL file to reach stable storage.WALSyncMethodAssignWaiting for data to reach stable storage while assigning WAL sync method.WALWriteWaiting for a write to a WAL file.
For tranches registered by extensions, the name is specified by extension
and this will be displayed as wait_event. It is quite
possible that user has registered the tranche in one of the backends (by
having allocation in dynamic shared memory) in which case other backends
won't have that information, so we display extension for such
cases.
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 | ProcArrayLock
(2 rows)
pg_stat_replication ViewColumnTypeDescriptionpidintegerProcess ID of a WAL sender processusesysidoidOID of the user logged into this WAL sender processusenamenameName of the user logged into this WAL sender processapplication_nametextName of the application that is connected
to this WAL senderclient_addrinetIP 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_hostnametextHost 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 is enabled.
client_portintegerTCP port number that the client is using for communication
with this WAL sender, or -1 if a Unix socket is used
backend_starttimestamp with time zoneTime when this process was started, i.e., when the
client connected to this WAL sender
backend_xminxidThis standby's xmin horizon reported
by .statetextCurrent 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_lsnpg_lsnLast write-ahead log location sent on this connectionwrite_lsnpg_lsnLast write-ahead log location written to disk by this standby
serverflush_lsnpg_lsnLast write-ahead log location flushed to disk by this standby
serverreplay_lsnpg_lsnLast write-ahead log location replayed into the database on this
standby serverwrite_lagintervalTime 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_lagintervalTime 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_lagintervalTime 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_priorityintegerPriority 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_statetextSynchronous 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_timetimestamp with time zoneSend time of last reply message received from standby serverspill_bytesbigintAmount of decoded transaction data spilled to disk.spill_txnsbigintNumber of transactions spilled to disk after the memory used by
logical decoding exceeds logical_decoding_work_mem. The
counter gets incremented both for toplevel transactions and
subtransactions.spill_countbigintNumber of times transactions were spilled to disk. Transactions
may get spilled repeatedly, and this counter gets incremented on every
such invocation.
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.
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_wal_receiver ViewColumnTypeDescriptionpidintegerProcess ID of the WAL receiver processstatustextActivity status of the WAL receiver processreceive_start_lsnpg_lsnFirst write-ahead log location used when WAL receiver is
startedreceive_start_tliintegerFirst timeline number used when WAL receiver is startedreceived_lsnpg_lsnLast 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 startedreceived_tliintegerTimeline 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
last_msg_send_timetimestamp with time zoneSend time of last message received from origin WAL senderlast_msg_receipt_timetimestamp with time zoneReceipt time of last message received from origin WAL senderlatest_end_lsnpg_lsnLast write-ahead log location reported to origin WAL senderlatest_end_timetimestamp with time zoneTime of last write-ahead log location reported to origin WAL senderslot_nametextReplication slot name used by this WAL receiversender_hosttext
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 /.)
sender_portinteger
Port number of the PostgreSQL instance
this WAL receiver is connected to.
conninfotext
Connection string used by this WAL receiver,
with security-sensitive fields obfuscated.
The pg_stat_wal_receiver view will contain only
one row, showing statistics about the WAL receiver from that receiver's
connected server.
pg_stat_subscription ViewColumnTypeDescriptionsubidoidOID of the subscriptionsubnametextName of the subscriptionpidintegerProcess ID of the subscription worker processrelidOidOID of the relation that the worker is synchronizing; null for the
main apply workerreceived_lsnpg_lsnLast write-ahead log location received, the initial value of
this field being 0last_msg_send_timetimestamp with time zoneSend time of last message received from origin WAL senderlast_msg_receipt_timetimestamp with time zoneReceipt time of last message received from origin WAL sender
latest_end_lsnpg_lsnLast write-ahead log location reported to origin WAL sender
latest_end_timetimestamp with time zoneTime of last write-ahead log location reported to origin WAL
sender
The pg_stat_subscription view will contain one
row per subscription for main worker (with null PID if the worker is
not running), and additional rows for workers handling the initial data
copy of the subscribed tables.
pg_stat_ssl ViewColumnTypeDescriptionpidintegerProcess ID of a backend or WAL sender processsslbooleanTrue if SSL is used on this connectionversiontextVersion of SSL in use, or NULL if SSL is not in use
on this connectionciphertextName of SSL cipher in use, or NULL if SSL is not in use
on this connectionbitsintegerNumber of bits in the encryption algorithm used, or NULL
if SSL is not used on this connectioncompressionbooleanTrue if SSL compression is in use, false if not,
or NULL if SSL is not in use on this connectionclient_dntextDistinguished 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 NAMEDATALEN (64 characters
in a standard build).
client_serialnumericSerial 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).issuer_dntextDN 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 client_dn.
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.
pg_stat_gssapi ViewColumnTypeDescriptionpidintegerProcess ID of a backendgss_authenticatedbooleanTrue if GSSAPI authentication was used for this connectionprincipaltextPrincipal 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
NAMEDATALEN (64 characters in a standard build).
encryptedbooleanTrue if GSSAPI encryption is in use on this connection
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.
pg_stat_archiver ViewColumnTypeDescriptionarchived_countbigintNumber of WAL files that have been successfully archivedlast_archived_waltextName of the last WAL file successfully archivedlast_archived_timetimestamp with time zoneTime of the last successful archive operationfailed_countbigintNumber of failed attempts for archiving WAL fileslast_failed_waltextName of the WAL file of the last failed archival operationlast_failed_timetimestamp with time zoneTime of the last failed archival operationstats_resettimestamp with time zoneTime at which these statistics were last reset
The pg_stat_archiver view will always have a
single row, containing data about the archiver process of the cluster.
pg_stat_bgwriter ViewColumnTypeDescriptioncheckpoints_timedbigintNumber of scheduled checkpoints that have been performedcheckpoints_reqbigintNumber of requested checkpoints that have been performedcheckpoint_write_timedouble precision
Total amount of time that has been spent in the portion of
checkpoint processing where files are written to disk, in milliseconds
checkpoint_sync_timedouble precision
Total amount of time that has been spent in the portion of
checkpoint processing where files are synchronized to disk, in
milliseconds
buffers_checkpointbigintNumber of buffers written during checkpointsbuffers_cleanbigintNumber of buffers written by the background writermaxwritten_cleanbigintNumber of times the background writer stopped a cleaning
scan because it had written too many buffersbuffers_backendbigintNumber of buffers written directly by a backendbuffers_backend_fsyncbigintNumber of times a backend had to execute its own
fsync call (normally the background writer handles those
even when the backend does its own write)buffers_allocbigintNumber of buffers allocatedstats_resettimestamp with time zoneTime at which these statistics were last reset
The pg_stat_bgwriter view will always have a
single row, containing global data for the cluster.
pg_stat_database ViewColumnTypeDescriptiondatidoidOID of this database, or 0 for objects belonging to a shared
relationdatnamenameName of this database, or NULL for the shared
objects.numbackendsintegerNumber 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_commitbigintNumber of transactions in this database that have been
committedxact_rollbackbigintNumber of transactions in this database that have been
rolled backblks_readbigintNumber of disk blocks read in this databaseblks_hitbigintNumber 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_returnedbigintNumber of rows returned by queries in this databasetup_fetchedbigintNumber of rows fetched by queries in this databasetup_insertedbigintNumber of rows inserted by queries in this databasetup_updatedbigintNumber of rows updated by queries in this databasetup_deletedbigintNumber of rows deleted by queries in this databaseconflictsbigintNumber of queries canceled due to conflicts with recovery
in this database. (Conflicts occur only on standby servers; see
for details.)
temp_filesbigintNumber 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
setting.
temp_bytesbigintTotal 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 setting.
deadlocksbigintNumber of deadlocks detected in this databasechecksum_failuresbigintNumber of data page checksum failures detected in this
database (or on a shared object), or NULL if data checksums are not
enabled.checksum_last_failuretimestamp with time zoneTime 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_timedouble precisionTime spent reading data file blocks by backends in this database,
in millisecondsblk_write_timedouble precisionTime spent writing data file blocks by backends in this database,
in millisecondsstats_resettimestamp with time zoneTime at which these statistics were last reset
The pg_stat_database view will contain one row
for each database in the cluster, plus one for the shared objects, showing
database-wide statistics.
pg_stat_database_conflicts ViewColumnTypeDescriptiondatidoidOID of a databasedatnamenameName of this databaseconfl_tablespacebigintNumber of queries in this database that have been canceled due to
dropped tablespacesconfl_lockbigintNumber of queries in this database that have been canceled due to
lock timeoutsconfl_snapshotbigintNumber of queries in this database that have been canceled due to
old snapshotsconfl_bufferpinbigintNumber of queries in this database that have been canceled due to
pinned buffersconfl_deadlockbigintNumber of queries in this database that have been canceled due to
deadlocks
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 master servers.
pg_stat_all_tables ViewColumnTypeDescriptionrelidoidOID of a tableschemanamenameName of the schema that this table is inrelnamenameName of this tableseq_scanbigintNumber of sequential scans initiated on this tableseq_tup_readbigintNumber of live rows fetched by sequential scansidx_scanbigintNumber of index scans initiated on this tableidx_tup_fetchbigintNumber of live rows fetched by index scansn_tup_insbigintNumber of rows insertedn_tup_updbigintNumber of rows updated (includes HOT updated rows)n_tup_delbigintNumber of rows deletedn_tup_hot_updbigintNumber of rows HOT updated (i.e., with no separate index
update required)n_live_tupbigintEstimated number of live rowsn_dead_tupbigintEstimated number of dead rowsn_mod_since_analyzebigintEstimated number of rows modified since this table was last analyzedlast_vacuumtimestamp with time zoneLast time at which this table was manually vacuumed
(not counting VACUUM FULL)last_autovacuumtimestamp with time zoneLast time at which this table was vacuumed by the autovacuum
daemonlast_analyzetimestamp with time zoneLast time at which this table was manually analyzedlast_autoanalyzetimestamp with time zoneLast time at which this table was analyzed by the autovacuum
daemonvacuum_countbigintNumber of times this table has been manually vacuumed
(not counting VACUUM FULL)autovacuum_countbigintNumber of times this table has been vacuumed by the autovacuum
daemonanalyze_countbigintNumber of times this table has been manually analyzedautoanalyze_countbigintNumber of times this table has been analyzed by the autovacuum
daemon
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.
pg_stat_all_indexes ViewColumnTypeDescriptionrelidoidOID of the table for this indexindexrelidoidOID of this indexschemanamenameName of the schema this index is inrelnamenameName of the table for this indexindexrelnamenameName of this indexidx_scanbigintNumber of index scans initiated on this indexidx_tup_readbigintNumber of index entries returned by scans on this indexidx_tup_fetchbigintNumber of live table rows fetched by simple index scans using this
index
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.
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 ViewColumnTypeDescriptionrelidoidOID of a tableschemanamenameName of the schema that this table is inrelnamenameName of this tableheap_blks_readbigintNumber of disk blocks read from this tableheap_blks_hitbigintNumber of buffer hits in this tableidx_blks_readbigintNumber of disk blocks read from all indexes on this tableidx_blks_hitbigintNumber of buffer hits in all indexes on this tabletoast_blks_readbigintNumber of disk blocks read from this table's TOAST table (if any)toast_blks_hitbigintNumber of buffer hits in this table's TOAST table (if any)tidx_blks_readbigintNumber of disk blocks read from this table's TOAST table indexes (if any)tidx_blks_hitbigintNumber of buffer hits in this table's TOAST table indexes (if any)
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.
pg_statio_all_indexes ViewColumnTypeDescriptionrelidoidOID of the table for this indexindexrelidoidOID of this indexschemanamenameName of the schema this index is inrelnamenameName of the table for this indexindexrelnamenameName of this indexidx_blks_readbigintNumber of disk blocks read from this indexidx_blks_hitbigintNumber of buffer hits in this index
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.
pg_statio_all_sequences ViewColumnTypeDescriptionrelidoidOID of a sequenceschemanamenameName of the schema this sequence is inrelnamenameName of this sequenceblks_readbigintNumber of disk blocks read from this sequenceblks_hitbigintNumber of buffer hits in this sequence
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.
pg_stat_user_functions ViewColumnTypeDescriptionfuncidoidOID of a functionschemanamenameName of the schema this function is infuncnamenameName of this functioncallsbigintNumber of times this function has been calledtotal_timedouble precisionTotal time spent in this function and all other functions
called by it, in millisecondsself_timedouble precisionTotal time spent in this function itself, not including
other functions called by it, in milliseconds
The pg_stat_user_functions view will contain
one row for each tracked function, showing statistics about executions of
that function. The parameter
controls exactly which functions are tracked.
Statistics Functions
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 .
Additional Statistics FunctionsFunctionReturn TypeDescriptionpg_backend_pid()integer
Process ID of the server process handling the current session
pg_stat_get_activity(integer)pg_stat_get_activitysetof 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_snapshot_timestamp()pg_stat_get_snapshot_timestamptimestamp with time zone
Returns the timestamp of the current statistics snapshot
pg_stat_clear_snapshot()pg_stat_clear_snapshotvoid
Discard the current statistics snapshot
pg_stat_reset()pg_stat_resetvoid
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)pg_stat_reset_sharedvoid
Reset some cluster-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_single_table_counters(oid)pg_stat_reset_single_table_countersvoid
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)pg_stat_reset_single_function_countersvoid
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 .
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;
Per-Backend Statistics FunctionsFunctionReturn TypeDescriptionpg_stat_get_backend_idset()setof integerSet of currently active backend ID numbers (from 1 to the
number of active backends)pg_stat_get_backend_activity(integer)textText of this backend's most recent querypg_stat_get_backend_activity_start(integer)timestamp with time zoneTime when the most recent query was startedpg_stat_get_backend_client_addr(integer)inetIP address of the client connected to this backendpg_stat_get_backend_client_port(integer)integerTCP port number that the client is using for communicationpg_stat_get_backend_dbid(integer)oidOID of the database this backend is connected topg_stat_get_backend_pid(integer)integerProcess ID of this backendpg_stat_get_backend_start(integer)timestamp with time zoneTime when this process was startedpg_stat_get_backend_userid(integer)oidOID of the user logged into this backendpg_stat_get_backend_wait_event_type(integer)textWait event type name if backend is currently waiting, otherwise NULL.
See for details.
pg_stat_get_backend_wait_event(integer)textWait event name if backend is currently waiting, otherwise NULL.
See for details.
pg_stat_get_backend_xact_start(integer)timestamp with time zoneTime when the current transaction was started
Viewing Lockslockmonitoring
Another useful tool for monitoring database activity is the
pg_locks system table. It allows the
database administrator to view information about the outstanding
locks in the lock manager. For example, this capability can be used
to:
View all the locks currently outstanding, all the locks on
relations in a particular database, all the locks on a
particular relation, or all the locks held by a particular
PostgreSQL session.
Determine the relation in the current database with the most
ungranted locks (which might be a source of contention among
database clients).
Determine the effect of lock contention on overall database
performance, as well as the extent to which contention varies
with overall database traffic.
Details of the pg_locks view appear in
.
For more information on locking and managing concurrency with
PostgreSQL, refer to .
Progress ReportingPostgreSQL has the ability to report the progress of
certain commands during command execution. Currently, the only commands
which support progress reporting are CREATE INDEX,
VACUUM and
CLUSTER. This may be expanded in the future.
CREATE INDEX Progress Reporting
Whenever CREATE INDEX or REINDEX is running, the
pg_stat_progress_create_index view will contain
one row for each backend that is currently creating indexes. The tables
below describe the information that will be reported and provide information
about how to interpret it.
pg_stat_progress_create_index ViewColumnTypeDescriptionpidintegerProcess ID of backend.datidoidOID of the database to which this backend is connected.datnamenameName of the database to which this backend is connected.relidoidOID of the table on which the index is being created.index_relidoidOID of the index being created or reindexed. During a
non-concurrent CREATE INDEX, this is 0.commandtext
The command that is running: CREATE INDEX,
CREATE INDEX CONCURRENTLY,
REINDEX, or REINDEX CONCURRENTLY.
phasetext
Current processing phase of index creation. See .
lockers_totalbigint
Total number of lockers to wait for, when applicable.
lockers_donebigint
Number of lockers already waited for.
current_locker_pidbigint
Process ID of the locker currently being waited for.
blocks_totalbigint
Total number of blocks to be processed in the current phase.
blocks_donebigint
Number of blocks already processed in the current phase.
tuples_totalbigint
Total number of tuples to be processed in the current phase.
tuples_donebigint
Number of tuples already processed in the current phase.
partitions_totalbigint
When creating an index on a partitioned table, this column is set to
the total number of partitions on which the index is to be created.
partitions_donebigint
When creating an index on a partitioned table, this column is set to
the number of partitions on which the index has been completed.
CREATE INDEX PhasesPhaseDescriptioninitializingCREATE INDEX or REINDEX is preparing to create the index. This
phase is expected to be very brief.
waiting for writers before buildCREATE INDEX CONCURRENTLY or REINDEX CONCURRENTLY is waiting for transactions
with write locks that can potentially see the table to finish.
This phase is skipped when not in concurrent mode.
Columns lockers_total, lockers_done
and current_locker_pid contain the progress
information for this phase.
building index
The index is being built by the access method-specific code. In this phase,
access methods that support progress reporting fill in their own progress data,
and the subphase is indicated in this column. Typically,
blocks_total and blocks_done
will contain progress data, as well as potentially
tuples_total and tuples_done.
waiting for writers before validationCREATE INDEX CONCURRENTLY or REINDEX CONCURRENTLY is waiting for transactions
with write locks that can potentially write into the table to finish.
This phase is skipped when not in concurrent mode.
Columns lockers_total, lockers_done
and current_locker_pid contain the progress
information for this phase.
index validation: scanning indexCREATE INDEX CONCURRENTLY is scanning the index searching
for tuples that need to be validated.
This phase is skipped when not in concurrent mode.
Columns blocks_total (set to the total size of the index)
and blocks_done contain the progress information for this phase.
index validation: sorting tuplesCREATE INDEX CONCURRENTLY is sorting the output of the
index scanning phase.
index validation: scanning tableCREATE INDEX CONCURRENTLY is scanning the table
to validate the index tuples collected in the previous two phases.
This phase is skipped when not in concurrent mode.
Columns blocks_total (set to the total size of the table)
and blocks_done contain the progress information for this phase.
waiting for old snapshotsCREATE INDEX CONCURRENTLY or REINDEX CONCURRENTLY is waiting for transactions
that can potentially see the table to release their snapshots. This
phase is skipped when not in concurrent mode.
Columns lockers_total, lockers_done
and current_locker_pid contain the progress
information for this phase.
waiting for readers before marking deadREINDEX CONCURRENTLY is waiting for transactions
with read locks on the table to finish, before marking the old index dead.
This phase is skipped when not in concurrent mode.
Columns lockers_total, lockers_done
and current_locker_pid contain the progress
information for this phase.
waiting for readers before droppingREINDEX CONCURRENTLY is waiting for transactions
with read locks on the table to finish, before dropping the old index.
This phase is skipped when not in concurrent mode.
Columns lockers_total, lockers_done
and current_locker_pid contain the progress
information for this phase.
VACUUM Progress Reporting
Whenever VACUUM is running, the
pg_stat_progress_vacuum view will contain
one row for each backend (including autovacuum worker processes) that is
currently vacuuming. The tables below describe the information
that will be reported and provide information about how to interpret it.
Progress for VACUUM FULL commands is reported via
pg_stat_progress_cluster
because both VACUUM FULL and CLUSTER
rewrite the table, while regular VACUUM only modifies it
in place. See .
pg_stat_progress_vacuum ViewColumnTypeDescriptionpidintegerProcess ID of backend.datidoidOID of the database to which this backend is connected.datnamenameName of the database to which this backend is connected.relidoidOID of the table being vacuumed.phasetext
Current processing phase of vacuum. See .
heap_blks_totalbigint
Total number of heap blocks in the table. This number is reported
as of the beginning of the scan; blocks added later will not be (and
need not be) visited by this VACUUM.
heap_blks_scannedbigint
Number of heap blocks scanned. Because the
visibility map is used to optimize scans,
some blocks will be skipped without inspection; skipped blocks are
included in this total, so that this number will eventually become
equal to heap_blks_total when the vacuum is complete.
This counter only advances when the phase is scanning heap.
heap_blks_vacuumedbigint
Number of heap blocks vacuumed. Unless the table has no indexes, this
counter only advances when the phase is vacuuming heap.
Blocks that contain no dead tuples are skipped, so the counter may
sometimes skip forward in large increments.
index_vacuum_countbigint
Number of completed index vacuum cycles.
max_dead_tuplesbigint
Number of dead tuples that we can store before needing to perform
an index vacuum cycle, based on
.
num_dead_tuplesbigint
Number of dead tuples collected since the last index vacuum cycle.
VACUUM PhasesPhaseDescriptioninitializingVACUUM is preparing to begin scanning the heap. This
phase is expected to be very brief.
scanning heapVACUUM is currently scanning the heap. It will prune and
defragment each page if required, and possibly perform freezing
activity. The heap_blks_scanned column can be used
to monitor the progress of the scan.
vacuuming indexesVACUUM is currently vacuuming the indexes. If a table has
any indexes, this will happen at least once per vacuum, after the heap
has been completely scanned. It may happen multiple times per vacuum
if is insufficient to
store the number of dead tuples found.
vacuuming heapVACUUM is currently vacuuming the heap. Vacuuming the heap
is distinct from scanning the heap, and occurs after each instance of
vacuuming indexes. If heap_blks_scanned is less than
heap_blks_total, the system will return to scanning
the heap after this phase is completed; otherwise, it will begin
cleaning up indexes after this phase is completed.
cleaning up indexesVACUUM is currently cleaning up indexes. This occurs after
the heap has been completely scanned and all vacuuming of the indexes
and the heap has been completed.
truncating heapVACUUM is currently truncating the heap so as to return
empty pages at the end of the relation to the operating system. This
occurs after cleaning up indexes.
performing final cleanupVACUUM is performing final cleanup. During this phase,
VACUUM will vacuum the free space map, update statistics
in pg_class, and report statistics to the statistics
collector. When this phase is completed, VACUUM will end.
CLUSTER Progress Reporting
Whenever CLUSTER or VACUUM FULL is
running, the pg_stat_progress_cluster view will
contain a row for each backend that is currently running either command.
The tables below describe the information that will be reported and
provide information about how to interpret it.
pg_stat_progress_cluster ViewColumnTypeDescriptionpidintegerProcess ID of backend.datidoidOID of the database to which this backend is connected.datnamenameName of the database to which this backend is connected.relidoidOID of the table being clustered.commandtext
The command that is running. Either CLUSTER or VACUUM FULL.
phasetext
Current processing phase. See .
cluster_index_relidoid
If the table is being scanned using an index, this is the OID of the
index being used; otherwise, it is zero.
heap_tuples_scannedbigint
Number of heap tuples scanned.
This counter only advances when the phase is
seq scanning heap,
index scanning heap
or writing new heap.
heap_tuples_writtenbigint
Number of heap tuples written.
This counter only advances when the phase is
seq scanning heap,
index scanning heap
or writing new heap.
heap_blks_totalbigint
Total number of heap blocks in the table. This number is reported
as of the beginning of seq scanning heap.
heap_blks_scannedbigint
Number of heap blocks scanned. This counter only advances when the
phase is seq scanning heap.
index_rebuild_countbigint
Number of indexes rebuilt. This counter only advances when the phase
is rebuilding index.
CLUSTER and VACUUM FULL PhasesPhaseDescriptioninitializing
The command is preparing to begin scanning the heap. This phase is
expected to be very brief.
seq scanning heap
The command is currently scanning the table using a sequential scan.
index scanning heapCLUSTER is currently scanning the table using an index scan.
sorting tuplesCLUSTER is currently sorting tuples.
writing new heapCLUSTER is currently writing the new heap.
swapping relation files
The command is currently swapping newly-built files into place.
rebuilding index
The command is currently rebuilding an index.
performing final cleanup
The command is performing final cleanup. When this phase is
completed, CLUSTER
or VACUUM FULL will end.
Dynamic TracingDTracePostgreSQL provides facilities to support
dynamic tracing of the database server. This allows an external
utility to be called at specific points in the code and thereby trace
execution.
A number of probes or trace points are already inserted into the source
code. These probes are intended to be used by database developers and
administrators. By default the probes are not compiled into
PostgreSQL; the user needs to explicitly tell
the configure script to make the probes available.
Currently, the
DTrace
utility is supported, which, at the time of this writing, is available
on Solaris, macOS, FreeBSD, NetBSD, and Oracle Linux. The
SystemTap project
for Linux provides a DTrace equivalent and can also be used. Supporting other dynamic
tracing utilities is theoretically possible by changing the definitions for
the macros in src/include/utils/probes.h.
Compiling for Dynamic Tracing
By default, probes are not available, so you will need to
explicitly tell the configure script to make the probes available
in PostgreSQL. To include DTrace support
specify to configure. See for further information.
Built-in Probes
A number of standard probes are provided in the source code,
as shown in ;
shows the types used in the probes. More probes can certainly be
added to enhance PostgreSQL's observability.
Built-in DTrace ProbesNameParametersDescriptiontransaction-start(LocalTransactionId)Probe that fires at the start of a new transaction.
arg0 is the transaction ID.transaction-commit(LocalTransactionId)Probe that fires when a transaction completes successfully.
arg0 is the transaction ID.transaction-abort(LocalTransactionId)Probe that fires when a transaction completes unsuccessfully.
arg0 is the transaction ID.query-start(const char *)Probe that fires when the processing of a query is started.
arg0 is the query string.query-done(const char *)Probe that fires when the processing of a query is complete.
arg0 is the query string.query-parse-start(const char *)Probe that fires when the parsing of a query is started.
arg0 is the query string.query-parse-done(const char *)Probe that fires when the parsing of a query is complete.
arg0 is the query string.query-rewrite-start(const char *)Probe that fires when the rewriting of a query is started.
arg0 is the query string.query-rewrite-done(const char *)Probe that fires when the rewriting of a query is complete.
arg0 is the query string.query-plan-start()Probe that fires when the planning of a query is started.query-plan-done()Probe that fires when the planning of a query is complete.query-execute-start()Probe that fires when the execution of a query is started.query-execute-done()Probe that fires when the execution of a query is complete.statement-status(const char *)Probe that fires anytime the server process updates its
pg_stat_activity.status.
arg0 is the new status string.checkpoint-start(int)Probe that fires when a checkpoint is started.
arg0 holds the bitwise flags used to distinguish different checkpoint
types, such as shutdown, immediate or force.checkpoint-done(int, int, int, int, int)Probe that fires when a checkpoint is complete.
(The probes listed next fire in sequence during checkpoint processing.)
arg0 is the number of buffers written. arg1 is the total number of
buffers. arg2, arg3 and arg4 contain the number of WAL files added,
removed and recycled respectively.clog-checkpoint-start(bool)Probe that fires when the CLOG portion of a checkpoint is started.
arg0 is true for normal checkpoint, false for shutdown
checkpoint.clog-checkpoint-done(bool)Probe that fires when the CLOG portion of a checkpoint is
complete. arg0 has the same meaning as for clog-checkpoint-start.subtrans-checkpoint-start(bool)Probe that fires when the SUBTRANS portion of a checkpoint is
started.
arg0 is true for normal checkpoint, false for shutdown
checkpoint.subtrans-checkpoint-done(bool)Probe that fires when the SUBTRANS portion of a checkpoint is
complete. arg0 has the same meaning as for
subtrans-checkpoint-start.multixact-checkpoint-start(bool)Probe that fires when the MultiXact portion of a checkpoint is
started.
arg0 is true for normal checkpoint, false for shutdown
checkpoint.multixact-checkpoint-done(bool)Probe that fires when the MultiXact portion of a checkpoint is
complete. arg0 has the same meaning as for
multixact-checkpoint-start.buffer-checkpoint-start(int)Probe that fires when the buffer-writing portion of a checkpoint
is started.
arg0 holds the bitwise flags used to distinguish different checkpoint
types, such as shutdown, immediate or force.buffer-sync-start(int, int)Probe that fires when we begin to write dirty buffers during
checkpoint (after identifying which buffers must be written).
arg0 is the total number of buffers.
arg1 is the number that are currently dirty and need to be written.buffer-sync-written(int)Probe that fires after each buffer is written during checkpoint.
arg0 is the ID number of the buffer.buffer-sync-done(int, int, int)Probe that fires when all dirty buffers have been written.
arg0 is the total number of buffers.
arg1 is the number of buffers actually written by the checkpoint process.
arg2 is the number that were expected to be written (arg1 of
buffer-sync-start); any difference reflects other processes flushing
buffers during the checkpoint.buffer-checkpoint-sync-start()Probe that fires after dirty buffers have been written to the
kernel, and before starting to issue fsync requests.buffer-checkpoint-done()Probe that fires when syncing of buffers to disk is
complete.twophase-checkpoint-start()Probe that fires when the two-phase portion of a checkpoint is
started.twophase-checkpoint-done()Probe that fires when the two-phase portion of a checkpoint is
complete.buffer-read-start(ForkNumber, BlockNumber, Oid, Oid, Oid, int, bool)Probe that fires when a buffer read is started.
arg0 and arg1 contain the fork and block numbers of the page (but
arg1 will be -1 if this is a relation extension request).
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.
arg6 is true for a relation extension request, false for normal
read.buffer-read-done(ForkNumber, BlockNumber, Oid, Oid, Oid, int, bool, bool)Probe that fires when a buffer read is complete.
arg0 and arg1 contain the fork and block numbers of the page (if this
is a relation extension request, arg1 now contains the block number
of the newly added block).
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.
arg6 is true for a relation extension request, false for normal
read.
arg7 is true if the buffer was found in the pool, false if not.buffer-flush-start(ForkNumber, BlockNumber, Oid, Oid, Oid)Probe that fires before issuing any write request for a shared
buffer.
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.buffer-flush-done(ForkNumber, BlockNumber, Oid, Oid, Oid)Probe that fires when a write request is complete. (Note
that this just reflects the time to pass the data to the kernel;
it's typically not actually been written to disk yet.)
The arguments are the same as for buffer-flush-start.buffer-write-dirty-start(ForkNumber, BlockNumber, Oid, Oid, Oid)Probe that fires when a server process begins to write a dirty
buffer. (If this happens often, it implies that
is too
small or the background writer control parameters need adjustment.)
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.buffer-write-dirty-done(ForkNumber, BlockNumber, Oid, Oid, Oid)Probe that fires when a dirty-buffer write is complete.
The arguments are the same as for buffer-write-dirty-start.wal-buffer-write-dirty-start()Probe that fires when a server process begins to write a
dirty WAL buffer because no more WAL buffer space is available.
(If this happens often, it implies that
is too small.)wal-buffer-write-dirty-done()Probe that fires when a dirty WAL buffer write is complete.wal-insert(unsigned char, unsigned char)Probe that fires when a WAL record is inserted.
arg0 is the resource manager (rmid) for the record.
arg1 contains the info flags.wal-switch()Probe that fires when a WAL segment switch is requested.smgr-md-read-start(ForkNumber, BlockNumber, Oid, Oid, Oid, int)Probe that fires when beginning to read a block from a relation.
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.smgr-md-read-done(ForkNumber, BlockNumber, Oid, Oid, Oid, int, int, int)Probe that fires when a block read is complete.
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.
arg6 is the number of bytes actually read, while arg7 is the number
requested (if these are different it indicates trouble).smgr-md-write-start(ForkNumber, BlockNumber, Oid, Oid, Oid, int)Probe that fires when beginning to write a block to a relation.
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.smgr-md-write-done(ForkNumber, BlockNumber, Oid, Oid, Oid, int, int, int)Probe that fires when a block write is complete.
arg0 and arg1 contain the fork and block numbers of the page.
arg2, arg3, and arg4 contain the tablespace, database, and relation OIDs
identifying the relation.
arg5 is the ID of the backend which created the temporary relation for a
local buffer, or InvalidBackendId (-1) for a shared buffer.
arg6 is the number of bytes actually written, while arg7 is the number
requested (if these are different it indicates trouble).sort-start(int, bool, int, int, bool, int)Probe that fires when a sort operation is started.
arg0 indicates heap, index or datum sort.
arg1 is true for unique-value enforcement.
arg2 is the number of key columns.
arg3 is the number of kilobytes of work memory allowed.
arg4 is true if random access to the sort result is required.
arg5 indicates serial when 0, parallel worker when
1, or parallel leader when 2.sort-done(bool, long)Probe that fires when a sort is complete.
arg0 is true for external sort, false for internal sort.
arg1 is the number of disk blocks used for an external sort,
or kilobytes of memory used for an internal sort.lwlock-acquire(char *, LWLockMode)Probe that fires when an LWLock has been acquired.
arg0 is the LWLock's tranche.
arg1 is the requested lock mode, either exclusive or shared.lwlock-release(char *)Probe that fires when an LWLock has been released (but note
that any released waiters have not yet been awakened).
arg0 is the LWLock's tranche.lwlock-wait-start(char *, LWLockMode)Probe that fires when an LWLock was not immediately available and
a server process has begun to wait for the lock to become available.
arg0 is the LWLock's tranche.
arg1 is the requested lock mode, either exclusive or shared.lwlock-wait-done(char *, LWLockMode)Probe that fires when a server process has been released from its
wait for an LWLock (it does not actually have the lock yet).
arg0 is the LWLock's tranche.
arg1 is the requested lock mode, either exclusive or shared.lwlock-condacquire(char *, LWLockMode)Probe that fires when an LWLock was successfully acquired when the
caller specified no waiting.
arg0 is the LWLock's tranche.
arg1 is the requested lock mode, either exclusive or shared.lwlock-condacquire-fail(char *, LWLockMode)Probe that fires when an LWLock was not successfully acquired when
the caller specified no waiting.
arg0 is the LWLock's tranche.
arg1 is the requested lock mode, either exclusive or shared.lock-wait-start(unsigned int, unsigned int, unsigned int, unsigned int, unsigned int, LOCKMODE)Probe that fires when a request for a heavyweight lock (lmgr lock)
has begun to wait because the lock is not available.
arg0 through arg3 are the tag fields identifying the object being
locked. arg4 indicates the type of object being locked.
arg5 indicates the lock type being requested.lock-wait-done(unsigned int, unsigned int, unsigned int, unsigned int, unsigned int, LOCKMODE)Probe that fires when a request for a heavyweight lock (lmgr lock)
has finished waiting (i.e., has acquired the lock).
The arguments are the same as for lock-wait-start.deadlock-found()Probe that fires when a deadlock is found by the deadlock
detector.
Defined Types Used in Probe ParametersTypeDefinitionLocalTransactionIdunsigned intLWLockModeintLOCKMODEintBlockNumberunsigned intOidunsigned intForkNumberintboolunsigned char
Using Probes
The example below shows a DTrace script for analyzing transaction
counts in the system, as an alternative to snapshotting
pg_stat_database before and after a performance test:
#!/usr/sbin/dtrace -qs
postgresql$1:::transaction-start
{
@start["Start"] = count();
self->ts = timestamp;
}
postgresql$1:::transaction-abort
{
@abort["Abort"] = count();
}
postgresql$1:::transaction-commit
/self->ts/
{
@commit["Commit"] = count();
@time["Total time (ns)"] = sum(timestamp - self->ts);
self->ts=0;
}
When executed, the example D script gives output such as:
# ./txn_count.d `pgrep -n postgres` or ./txn_count.d <PID>
^C
Start 71
Commit 70
Total time (ns) 2312105013
SystemTap uses a different notation for trace scripts than DTrace does,
even though the underlying trace points are compatible. One point worth
noting is that at this writing, SystemTap scripts must reference probe
names using double underscores in place of hyphens. This is expected to
be fixed in future SystemTap releases.
You should remember that DTrace scripts need to be carefully written and
debugged, otherwise the trace information collected might
be meaningless. In most cases where problems are found it is the
instrumentation that is at fault, not the underlying system. When
discussing information found using dynamic tracing, be sure to enclose
the script used to allow that too to be checked and discussed.
Defining New Probes
New probes can be defined within the code wherever the developer
desires, though this will require a recompilation. Below are the steps
for inserting new probes:
Decide on probe names and data to be made available through the probes
Add the probe definitions to src/backend/utils/probes.d
Include pg_trace.h if it is not already present in the
module(s) containing the probe points, and insert
TRACE_POSTGRESQL probe macros at the desired locations
in the source code
Recompile and verify that the new probes are available
Example:
Here is an example of how you would add a probe to trace all new
transactions by transaction ID.
Decide that the probe will be named transaction-start and
requires a parameter of type LocalTransactionId
Add the probe definition to src/backend/utils/probes.d:
probe transaction__start(LocalTransactionId);
Note the use of the double underline in the probe name. In a DTrace
script using the probe, the double underline needs to be replaced with a
hyphen, so transaction-start is the name to document for
users.
At compile time, transaction__start is converted to a macro
called TRACE_POSTGRESQL_TRANSACTION_START (notice the
underscores are single here), which is available by including
pg_trace.h. Add the macro call to the appropriate location
in the source code. In this case, it looks like the following:
TRACE_POSTGRESQL_TRANSACTION_START(vxid.localTransactionId);
After recompiling and running the new binary, check that your newly added
probe is available by executing the following DTrace command. You
should see similar output:
# dtrace -ln transaction-start
ID PROVIDER MODULE FUNCTION NAME
18705 postgresql49878 postgres StartTransactionCommand transaction-start
18755 postgresql49877 postgres StartTransactionCommand transaction-start
18805 postgresql49876 postgres StartTransactionCommand transaction-start
18855 postgresql49875 postgres StartTransactionCommand transaction-start
18986 postgresql49873 postgres StartTransactionCommand transaction-start
There are a few things to be careful about when adding trace macros
to the C code:
You should take care that the data types specified for a probe's
parameters match the data types of the variables used in the macro.
Otherwise, you will get compilation errors.
On most platforms, if PostgreSQL is
built with , the arguments to a trace
macro will be evaluated whenever control passes through the
macro, even if no tracing is being done. This is
usually not worth worrying about if you are just reporting the
values of a few local variables. But beware of putting expensive
function calls into the arguments. If you need to do that,
consider protecting the macro with a check to see if the trace
is actually enabled:
if (TRACE_POSTGRESQL_TRANSACTION_START_ENABLED())
TRACE_POSTGRESQL_TRANSACTION_START(some_function(...));
Each trace macro has a corresponding ENABLED macro.