2 27.2. The Cumulative Statistics System #
4 27.2.1. Statistics Collection Configuration
5 27.2.2. Viewing Statistics
6 27.2.3. pg_stat_activity
7 27.2.4. pg_stat_replication
8 27.2.5. pg_stat_replication_slots
9 27.2.6. pg_stat_wal_receiver
10 27.2.7. pg_stat_recovery_prefetch
11 27.2.8. pg_stat_subscription
12 27.2.9. pg_stat_subscription_stats
14 27.2.11. pg_stat_gssapi
15 27.2.12. pg_stat_archiver
17 27.2.14. pg_stat_bgwriter
18 27.2.15. pg_stat_checkpointer
20 27.2.17. pg_stat_database
21 27.2.18. pg_stat_database_conflicts
22 27.2.19. pg_stat_all_tables
23 27.2.20. pg_stat_all_indexes
24 27.2.21. pg_statio_all_tables
25 27.2.22. pg_statio_all_indexes
26 27.2.23. pg_statio_all_sequences
27 27.2.24. pg_stat_user_functions
29 27.2.26. Statistics Functions
31 PostgreSQL's cumulative statistics system supports collection and
32 reporting of information about server activity. Presently, accesses to
33 tables and indexes in both disk-block and individual-row terms are
34 counted. The total number of rows in each table, and information about
35 vacuum and analyze actions for each table are also counted. If enabled,
36 calls to user-defined functions and the total time spent in each one
39 PostgreSQL also supports reporting dynamic information about exactly
40 what is going on in the system right now, such as the exact command
41 currently being executed by other server processes, and which other
42 connections exist in the system. This facility is independent of the
43 cumulative statistics system.
45 27.2.1. Statistics Collection Configuration #
47 Since collection of statistics adds some overhead to query execution,
48 the system can be configured to collect or not collect information.
49 This is controlled by configuration parameters that are normally set in
50 postgresql.conf. (See Chapter 19 for details about setting
51 configuration parameters.)
53 The parameter track_activities enables monitoring of the current
54 command being executed by any server process.
56 The parameter track_cost_delay_timing enables monitoring of cost-based
59 The parameter track_counts controls whether cumulative statistics are
60 collected about table and index accesses.
62 The parameter track_functions enables tracking of usage of user-defined
65 The parameter track_io_timing enables monitoring of block read, write,
66 extend, and fsync times.
68 The parameter track_wal_io_timing enables monitoring of WAL read, write
71 Normally these parameters are set in postgresql.conf so that they apply
72 to all server processes, but it is possible to turn them on or off in
73 individual sessions using the SET command. (To prevent ordinary users
74 from hiding their activity from the administrator, only superusers are
75 allowed to change these parameters with SET.)
77 Cumulative statistics are collected in shared memory. Every PostgreSQL
78 process collects statistics locally, then updates the shared data at
79 appropriate intervals. When a server, including a physical replica,
80 shuts down cleanly, a permanent copy of the statistics data is stored
81 in the pg_stat subdirectory, so that statistics can be retained across
82 server restarts. In contrast, when starting from an unclean shutdown
83 (e.g., after an immediate shutdown, a server crash, starting from a
84 base backup, and point-in-time recovery), all statistics counters are
87 27.2.2. Viewing Statistics #
89 Several predefined views, listed in Table 27.1, are available to show
90 the current state of the system. There are also several other views,
91 listed in Table 27.2, available to show the accumulated statistics.
92 Alternatively, one can build custom views using the underlying
93 cumulative statistics functions, as discussed in Section 27.2.26.
95 When using the cumulative statistics views and functions to monitor
96 collected data, it is important to realize that the information does
97 not update instantaneously. Each individual server process flushes out
98 accumulated statistics to shared memory just before going idle, but not
99 more frequently than once per PGSTAT_MIN_INTERVAL milliseconds (1
100 second unless altered while building the server); so a query or
101 transaction still in progress does not affect the displayed totals and
102 the displayed information lags behind actual activity. However,
103 current-query information collected by track_activities is always
106 Another important point is that when a server process is asked to
107 display any of the accumulated statistics, accessed values are cached
108 until the end of its current transaction in the default configuration.
109 So the statistics will show static information as long as you continue
110 the current transaction. Similarly, information about the current
111 queries of all sessions is collected when any such information is first
112 requested within a transaction, and the same information will be
113 displayed throughout the transaction. This is a feature, not a bug,
114 because it allows you to perform several queries on the statistics and
115 correlate the results without worrying that the numbers are changing
116 underneath you. When analyzing statistics interactively, or with
117 expensive queries, the time delta between accesses to individual
118 statistics can lead to significant skew in the cached statistics. To
119 minimize skew, stats_fetch_consistency can be set to snapshot, at the
120 price of increased memory usage for caching not-needed statistics data.
121 Conversely, if it's known that statistics are only accessed once,
122 caching accessed statistics is unnecessary and can be avoided by
123 setting stats_fetch_consistency to none. You can invoke
124 pg_stat_clear_snapshot() to discard the current transaction's
125 statistics snapshot or cached values (if any). The next use of
126 statistical information will (when in snapshot mode) cause a new
127 snapshot to be built or (when in cache mode) accessed statistics to be
130 A transaction can also see its own statistics (not yet flushed out to
131 the shared memory statistics) in the views pg_stat_xact_all_tables,
132 pg_stat_xact_sys_tables, pg_stat_xact_user_tables, and
133 pg_stat_xact_user_functions. These numbers do not act as stated above;
134 instead they update continuously throughout the transaction.
136 Some of the information in the dynamic statistics views shown in
137 Table 27.1 is security restricted. Ordinary users can only see all the
138 information about their own sessions (sessions belonging to a role that
139 they are a member of). In rows about other sessions, many columns will
140 be null. Note, however, that the existence of a session and its general
141 properties such as its sessions user and database are visible to all
142 users. Superusers and roles with privileges of built-in role
143 pg_read_all_stats can see all the information about all sessions.
145 Table 27.1. Dynamic Statistics Views
146 View Name Description
147 pg_stat_activity One row per server process, showing information
148 related to the current activity of that process, such as state and
149 current query. See pg_stat_activity for details.
150 pg_stat_replication One row per WAL sender process, showing statistics
151 about replication to that sender's connected standby server. See
152 pg_stat_replication for details.
153 pg_stat_wal_receiver Only one row, showing statistics about the WAL
154 receiver from that receiver's connected server. See
155 pg_stat_wal_receiver for details.
156 pg_stat_recovery_prefetch Only one row, showing statistics about blocks
157 prefetched during recovery. See pg_stat_recovery_prefetch for details.
158 pg_stat_subscription At least one row per subscription, showing
159 information about the subscription workers. See pg_stat_subscription
161 pg_stat_ssl One row per connection (regular and replication), showing
162 information about SSL used on this connection. See pg_stat_ssl for
164 pg_stat_gssapi One row per connection (regular and replication),
165 showing information about GSSAPI authentication and encryption used on
166 this connection. See pg_stat_gssapi for details.
167 pg_stat_progress_analyze One row for each backend (including autovacuum
168 worker processes) running ANALYZE, showing current progress. See
170 pg_stat_progress_create_index One row for each backend running CREATE
171 INDEX or REINDEX, showing current progress. See Section 27.4.4.
172 pg_stat_progress_vacuum One row for each backend (including autovacuum
173 worker processes) running VACUUM, showing current progress. See
175 pg_stat_progress_cluster One row for each backend running CLUSTER or
176 VACUUM FULL, showing current progress. See Section 27.4.2.
177 pg_stat_progress_basebackup One row for each WAL sender process
178 streaming a base backup, showing current progress. See Section 27.4.6.
179 pg_stat_progress_copy One row for each backend running COPY, showing
180 current progress. See Section 27.4.3.
182 Table 27.2. Collected Statistics Views
183 View Name Description
184 pg_stat_archiver One row only, showing statistics about the WAL
185 archiver process's activity. See pg_stat_archiver for details.
186 pg_stat_bgwriter One row only, showing statistics about the background
187 writer process's activity. See pg_stat_bgwriter for details.
188 pg_stat_checkpointer One row only, showing statistics about the
189 checkpointer process's activity. See pg_stat_checkpointer for details.
190 pg_stat_database One row per database, showing database-wide
191 statistics. See pg_stat_database for details.
192 pg_stat_database_conflicts One row per database, showing database-wide
193 statistics about query cancels due to conflict with recovery on standby
194 servers. See pg_stat_database_conflicts for details.
195 pg_stat_io One row for each combination of backend type, context, and
196 target object containing cluster-wide I/O statistics. See pg_stat_io
198 pg_stat_replication_slots One row per replication slot, showing
199 statistics about the replication slot's usage. See
200 pg_stat_replication_slots for details.
201 pg_stat_slru One row per SLRU, showing statistics of operations. See
202 pg_stat_slru for details.
203 pg_stat_subscription_stats One row per subscription, showing statistics
204 about errors and conflicts. See pg_stat_subscription_stats for details.
205 pg_stat_wal One row only, showing statistics about WAL activity. See
206 pg_stat_wal for details.
207 pg_stat_all_tables One row for each table in the current database,
208 showing statistics about accesses to that specific table. See
209 pg_stat_all_tables for details.
210 pg_stat_sys_tables Same as pg_stat_all_tables, except that only system
212 pg_stat_user_tables Same as pg_stat_all_tables, except that only user
214 pg_stat_xact_all_tables Similar to pg_stat_all_tables, but counts
215 actions taken so far within the current transaction (which are not yet
216 included in pg_stat_all_tables and related views). The columns for
217 numbers of live and dead rows and vacuum and analyze actions are not
218 present in this view.
219 pg_stat_xact_sys_tables Same as pg_stat_xact_all_tables, except that
220 only system tables are shown.
221 pg_stat_xact_user_tables Same as pg_stat_xact_all_tables, except that
222 only user tables are shown.
223 pg_stat_all_indexes One row for each index in the current database,
224 showing statistics about accesses to that specific index. See
225 pg_stat_all_indexes for details.
226 pg_stat_sys_indexes Same as pg_stat_all_indexes, except that only
227 indexes on system tables are shown.
228 pg_stat_user_indexes Same as pg_stat_all_indexes, except that only
229 indexes on user tables are shown.
230 pg_stat_user_functions One row for each tracked function, showing
231 statistics about executions of that function. See
232 pg_stat_user_functions for details.
233 pg_stat_xact_user_functions Similar to pg_stat_user_functions, but
234 counts only calls during the current transaction (which are not yet
235 included in pg_stat_user_functions).
236 pg_statio_all_tables One row for each table in the current database,
237 showing statistics about I/O on that specific table. See
238 pg_statio_all_tables for details.
239 pg_statio_sys_tables Same as pg_statio_all_tables, except that only
240 system tables are shown.
241 pg_statio_user_tables Same as pg_statio_all_tables, except that only
242 user tables are shown.
243 pg_statio_all_indexes One row for each index in the current database,
244 showing statistics about I/O on that specific index. See
245 pg_statio_all_indexes for details.
246 pg_statio_sys_indexes Same as pg_statio_all_indexes, except that only
247 indexes on system tables are shown.
248 pg_statio_user_indexes Same as pg_statio_all_indexes, except that only
249 indexes on user tables are shown.
250 pg_statio_all_sequences One row for each sequence in the current
251 database, showing statistics about I/O on that specific sequence. See
252 pg_statio_all_sequences for details.
253 pg_statio_sys_sequences Same as pg_statio_all_sequences, except that
254 only system sequences are shown. (Presently, no system sequences are
255 defined, so this view is always empty.)
256 pg_statio_user_sequences Same as pg_statio_all_sequences, except that
257 only user sequences are shown.
259 The per-index statistics are particularly useful to determine which
260 indexes are being used and how effective they are.
262 The pg_stat_io and pg_statio_ set of views are useful for determining
263 the effectiveness of the buffer cache. They can be used to calculate a
264 cache hit ratio. Note that while PostgreSQL's I/O statistics capture
265 most instances in which the kernel was invoked in order to perform I/O,
266 they do not differentiate between data which had to be fetched from
267 disk and that which already resided in the kernel page cache. Users are
268 advised to use the PostgreSQL statistics views in combination with
269 operating system utilities for a more complete picture of their
270 database's I/O performance.
272 27.2.3. pg_stat_activity #
274 The pg_stat_activity view will have one row per server process, showing
275 information related to the current activity of that process.
277 Table 27.3. pg_stat_activity View
285 OID of the database this backend is connected to
289 Name of the database this backend is connected to
293 Process ID of this backend
297 Process ID of the parallel group leader if this process is a parallel
298 query worker, or process ID of the leader apply worker if this process
299 is a parallel apply worker. NULL indicates that this process is a
300 parallel group leader or leader apply worker, or does not participate
301 in any parallel operation.
305 OID of the user logged into this backend
309 Name of the user logged into this backend
311 application_name text
313 Name of the application that is connected to this backend
317 IP address of the client connected to this backend. If this field is
318 null, it indicates either that the client is connected via a Unix
319 socket on the server machine or that this is an internal process such
324 Host name of the connected client, as reported by a reverse DNS lookup
325 of client_addr. This field will only be non-null for IP connections,
326 and only when log_hostname is enabled.
330 TCP port number that the client is using for communication with this
331 backend, or -1 if a Unix socket is used. If this field is null, it
332 indicates that this is an internal server process.
334 backend_start timestamp with time zone
336 Time when this process was started. For client backends, this is the
337 time the client connected to the server.
339 xact_start timestamp with time zone
341 Time when this process' current transaction was started, or null if no
342 transaction is active. If the current query is the first of its
343 transaction, this column is equal to the query_start column.
345 query_start timestamp with time zone
347 Time when the currently active query was started, or if state is not
348 active, when the last query was started
350 state_change timestamp with time zone
352 Time when the state was last changed
356 The type of event for which the backend is waiting, if any; otherwise
357 NULL. See Table 27.4.
361 Wait event name if backend is currently waiting, otherwise NULL. See
362 Table 27.5 through Table 27.13.
366 Current overall state of this backend. Possible values are:
367 * starting: The backend is in initial startup. Client authentication
368 is performed during this phase.
369 * active: The backend is executing a query.
370 * idle: The backend is waiting for a new client command.
371 * idle in transaction: The backend is in a transaction, but is not
372 currently executing a query.
373 * idle in transaction (aborted): This state is similar to idle in
374 transaction, except one of the statements in the transaction caused
376 * fastpath function call: The backend is executing a fast-path
378 * disabled: This state is reported if track_activities is disabled in
383 Top-level transaction identifier of this backend, if any; see
388 The current backend's xmin horizon.
392 Identifier of this backend's most recent query. If state is active this
393 field shows the identifier of the currently executing query. In all
394 other states, it shows the identifier of last query that was executed.
395 Query identifiers are not computed by default so this field will be
396 null unless compute_query_id parameter is enabled or a third-party
397 module that computes query identifiers is configured.
401 Text of this backend's most recent query. If state is active this field
402 shows the currently executing query. In all other states, it shows the
403 last query that was executed. By default the query text is truncated at
404 1024 bytes; this value can be changed via the parameter
405 track_activity_query_size.
409 Type of current backend. Possible types are autovacuum launcher,
410 autovacuum worker, logical replication launcher, logical replication
411 worker, parallel worker, background writer, client backend,
412 checkpointer, archiver, standalone backend, startup, walreceiver,
413 walsender, walwriter and walsummarizer. In addition, background workers
414 registered by extensions may have additional types.
418 The wait_event and state columns are independent. If a backend is in
419 the active state, it may or may not be waiting on some event. If the
420 state is active and wait_event is non-null, it means that a query is
421 being executed, but is being blocked somewhere in the system. To keep
422 the reporting overhead low, the system does not attempt to synchronize
423 different aspects of activity data for a backend. As a result,
424 ephemeral discrepancies may exist between the view's columns.
426 Table 27.4. Wait Event Types
427 Wait Event Type Description
428 Activity The server process is idle. This event type indicates a
429 process waiting for activity in its main processing loop. wait_event
430 will identify the specific wait point; see Table 27.5.
431 BufferPin The server process is waiting for exclusive access to a data
432 buffer. Buffer pin waits can be protracted if another process holds an
433 open cursor that last read data from the buffer in question. See
435 Client The server process is waiting for activity on a socket connected
436 to a user application. Thus, the server expects something to happen
437 that is independent of its internal processes. wait_event will identify
438 the specific wait point; see Table 27.7.
439 Extension The server process is waiting for some condition defined by
440 an extension module. See Table 27.8.
441 InjectionPoint The server process is waiting for an injection point to
442 reach an outcome defined in a test. See Section 36.10.14 for more
443 details. This type has no predefined wait points.
444 IO The server process is waiting for an I/O operation to complete.
445 wait_event will identify the specific wait point; see Table 27.9.
446 IPC The server process is waiting for some interaction with another
447 server process. wait_event will identify the specific wait point; see
449 Lock The server process is waiting for a heavyweight lock. Heavyweight
450 locks, also known as lock manager locks or simply locks, primarily
451 protect SQL-visible objects such as tables. However, they are also used
452 to ensure mutual exclusion for certain internal operations such as
453 relation extension. wait_event will identify the type of lock awaited;
455 LWLock The server process is waiting for a lightweight lock. Most such
456 locks protect a particular data structure in shared memory. wait_event
457 will contain a name identifying the purpose of the lightweight lock.
458 (Some locks have specific names; others are part of a group of locks
459 each with a similar purpose.) See Table 27.12.
460 Timeout The server process is waiting for a timeout to expire.
461 wait_event will identify the specific wait point; see Table 27.13.
463 Table 27.5. Wait Events of Type Activity
464 Activity Wait Event Description
465 ArchiverMain Waiting in main loop of archiver process.
466 AutovacuumMain Waiting in main loop of autovacuum launcher process.
467 BgwriterHibernate Waiting in background writer process, hibernating.
468 BgwriterMain Waiting in main loop of background writer process.
469 CheckpointerMain Waiting in main loop of checkpointer process.
470 CheckpointerShutdown Waiting for checkpointer process to be terminated.
471 IoWorkerMain Waiting in main loop of IO Worker process.
472 LogicalApplyMain Waiting in main loop of logical replication apply
474 LogicalLauncherMain Waiting in main loop of logical replication
476 LogicalParallelApplyMain Waiting in main loop of logical replication
477 parallel apply process.
478 RecoveryWalStream Waiting in main loop of startup process for WAL to
479 arrive, during streaming recovery.
480 ReplicationSlotsyncMain Waiting in main loop of slot sync worker.
481 ReplicationSlotsyncShutdown Waiting for slot sync worker to shut down.
482 SysloggerMain Waiting in main loop of syslogger process.
483 WalReceiverMain Waiting in main loop of WAL receiver process.
484 WalSenderMain Waiting in main loop of WAL sender process.
485 WalSummarizerWal Waiting in WAL summarizer for more WAL to be
487 WalWriterMain Waiting in main loop of WAL writer process.
489 Table 27.6. Wait Events of Type Bufferpin
490 BufferPin Wait Event Description
491 BufferPin Waiting to acquire an exclusive pin on a buffer.
493 Table 27.7. Wait Events of Type Client
494 Client Wait Event Description
495 ClientRead Waiting to read data from the client.
496 ClientWrite Waiting to write data to the client.
497 GssOpenServer Waiting to read data from the client while establishing a
499 LibpqwalreceiverConnect Waiting in WAL receiver to establish connection
501 LibpqwalreceiverReceive Waiting in WAL receiver to receive data from
503 SslOpenServer Waiting for SSL while attempting connection.
504 WaitForStandbyConfirmation Waiting for WAL to be received and flushed
505 by the physical standby.
506 WalSenderWaitForWal Waiting for WAL to be flushed in WAL sender
508 WalSenderWriteData Waiting for any activity when processing replies
509 from WAL receiver in WAL sender process.
511 Table 27.8. Wait Events of Type Extension
512 Extension Wait Event Description
513 Extension Waiting in an extension.
515 Table 27.9. Wait Events of Type Io
516 IO Wait Event Description
517 AioIoCompletion Waiting for another process to complete IO.
518 AioIoUringExecution Waiting for IO execution via io_uring.
519 AioIoUringSubmit Waiting for IO submission via io_uring.
520 BasebackupRead Waiting for base backup to read from a file.
521 BasebackupSync Waiting for data written by a base backup to reach
523 BasebackupWrite Waiting for base backup to write to a file.
524 BuffileRead Waiting for a read from a buffered file.
525 BuffileTruncate Waiting for a buffered file to be truncated.
526 BuffileWrite Waiting for a write to a buffered file.
527 ControlFileRead Waiting for a read from the pg_control file.
528 ControlFileSync Waiting for the pg_control file to reach durable
530 ControlFileSyncUpdate Waiting for an update to the pg_control file to
531 reach durable storage.
532 ControlFileWrite Waiting for a write to the pg_control file.
533 ControlFileWriteUpdate Waiting for a write to update the pg_control
535 CopyFileCopy Waiting for a file copy operation.
536 CopyFileRead Waiting for a read during a file copy operation.
537 CopyFileWrite Waiting for a write during a file copy operation.
538 DataFileExtend Waiting for a relation data file to be extended.
539 DataFileFlush Waiting for a relation data file to reach durable
541 DataFileImmediateSync Waiting for an immediate synchronization of a
542 relation data file to durable storage.
543 DataFilePrefetch Waiting for an asynchronous prefetch from a relation
545 DataFileRead Waiting for a read from a relation data file.
546 DataFileSync Waiting for changes to a relation data file to reach
548 DataFileTruncate Waiting for a relation data file to be truncated.
549 DataFileWrite Waiting for a write to a relation data file.
550 DsmAllocate Waiting for a dynamic shared memory segment to be
552 DsmFillZeroWrite Waiting to fill a dynamic shared memory backing file
554 LockFileAddtodatadirRead Waiting for a read while adding a line to the
555 data directory lock file.
556 LockFileAddtodatadirSync Waiting for data to reach durable storage
557 while adding a line to the data directory lock file.
558 LockFileAddtodatadirWrite Waiting for a write while adding a line to
559 the data directory lock file.
560 LockFileCreateRead Waiting to read while creating the data directory
562 LockFileCreateSync Waiting for data to reach durable storage while
563 creating the data directory lock file.
564 LockFileCreateWrite Waiting for a write while creating the data
566 LockFileRecheckdatadirRead Waiting for a read during recheck of the
567 data directory lock file.
568 LogicalRewriteCheckpointSync Waiting for logical rewrite mappings to
569 reach durable storage during a checkpoint.
570 LogicalRewriteMappingSync Waiting for mapping data to reach durable
571 storage during a logical rewrite.
572 LogicalRewriteMappingWrite Waiting for a write of mapping data during a
574 LogicalRewriteSync Waiting for logical rewrite mappings to reach
576 LogicalRewriteTruncate Waiting for truncate of mapping data during a
578 LogicalRewriteWrite Waiting for a write of logical rewrite mappings.
579 RelationMapRead Waiting for a read of the relation map file.
580 RelationMapReplace Waiting for durable replacement of a relation map
582 RelationMapWrite Waiting for a write to the relation map file.
583 ReorderBufferRead Waiting for a read during reorder buffer management.
584 ReorderBufferWrite Waiting for a write during reorder buffer
586 ReorderLogicalMappingRead Waiting for a read of a logical mapping
587 during reorder buffer management.
588 ReplicationSlotRead Waiting for a read from a replication slot control
590 ReplicationSlotRestoreSync Waiting for a replication slot control file
591 to reach durable storage while restoring it to memory.
592 ReplicationSlotSync Waiting for a replication slot control file to
593 reach durable storage.
594 ReplicationSlotWrite Waiting for a write to a replication slot control
596 SlruFlushSync Waiting for SLRU data to reach durable storage during a
597 checkpoint or database shutdown.
598 SlruRead Waiting for a read of an SLRU page.
599 SlruSync Waiting for SLRU data to reach durable storage following a
601 SlruWrite Waiting for a write of an SLRU page.
602 SnapbuildRead Waiting for a read of a serialized historical catalog
604 SnapbuildSync Waiting for a serialized historical catalog snapshot to
605 reach durable storage.
606 SnapbuildWrite Waiting for a write of a serialized historical catalog
608 TimelineHistoryFileSync Waiting for a timeline history file received
609 via streaming replication to reach durable storage.
610 TimelineHistoryFileWrite Waiting for a write of a timeline history file
611 received via streaming replication.
612 TimelineHistoryRead Waiting for a read of a timeline history file.
613 TimelineHistorySync Waiting for a newly created timeline history file
614 to reach durable storage.
615 TimelineHistoryWrite Waiting for a write of a newly created timeline
617 TwophaseFileRead Waiting for a read of a two phase state file.
618 TwophaseFileSync Waiting for a two phase state file to reach durable
620 TwophaseFileWrite Waiting for a write of a two phase state file.
621 VersionFileSync Waiting for the version file to reach durable storage
622 while creating a database.
623 VersionFileWrite Waiting for the version file to be written while
625 WalsenderTimelineHistoryRead Waiting for a read from a timeline history
626 file during a walsender timeline command.
627 WalBootstrapSync Waiting for WAL to reach durable storage during
629 WalBootstrapWrite Waiting for a write of a WAL page during
631 WalCopyRead Waiting for a read when creating a new WAL segment by
632 copying an existing one.
633 WalCopySync Waiting for a new WAL segment created by copying an
634 existing one to reach durable storage.
635 WalCopyWrite Waiting for a write when creating a new WAL segment by
636 copying an existing one.
637 WalInitSync Waiting for a newly initialized WAL file to reach durable
639 WalInitWrite Waiting for a write while initializing a new WAL file.
640 WalRead Waiting for a read from a WAL file.
641 WalSummaryRead Waiting for a read from a WAL summary file.
642 WalSummaryWrite Waiting for a write to a WAL summary file.
643 WalSync Waiting for a WAL file to reach durable storage.
644 WalSyncMethodAssign Waiting for data to reach durable storage while
645 assigning a new WAL sync method.
646 WalWrite Waiting for a write to a WAL file.
648 Table 27.10. Wait Events of Type Ipc
649 IPC Wait Event Description
650 AppendReady Waiting for subplan nodes of an Append plan node to be
652 ArchiveCleanupCommand Waiting for archive_cleanup_command to complete.
653 ArchiveCommand Waiting for archive_command to complete.
654 BackendTermination Waiting for the termination of another backend.
655 BackupWaitWalArchive Waiting for WAL files required for a backup to be
656 successfully archived.
657 BgworkerShutdown Waiting for background worker to shut down.
658 BgworkerStartup Waiting for background worker to start up.
659 BtreePage Waiting for the page number needed to continue a parallel
660 B-tree scan to become available.
661 BufferIo Waiting for buffer I/O to complete.
662 CheckpointDelayComplete Waiting for a backend that blocks a checkpoint
664 CheckpointDelayStart Waiting for a backend that blocks a checkpoint
666 CheckpointDone Waiting for a checkpoint to complete.
667 CheckpointStart Waiting for a checkpoint to start.
668 ExecuteGather Waiting for activity from a child process while executing
670 HashBatchAllocate Waiting for an elected Parallel Hash participant to
671 allocate a hash table.
672 HashBatchElect Waiting to elect a Parallel Hash participant to allocate
674 HashBatchLoad Waiting for other Parallel Hash participants to finish
675 loading a hash table.
676 HashBuildAllocate Waiting for an elected Parallel Hash participant to
677 allocate the initial hash table.
678 HashBuildElect Waiting to elect a Parallel Hash participant to allocate
679 the initial hash table.
680 HashBuildHashInner Waiting for other Parallel Hash participants to
681 finish hashing the inner relation.
682 HashBuildHashOuter Waiting for other Parallel Hash participants to
683 finish partitioning the outer relation.
684 HashGrowBatchesDecide Waiting to elect a Parallel Hash participant to
685 decide on future batch growth.
686 HashGrowBatchesElect Waiting to elect a Parallel Hash participant to
687 allocate more batches.
688 HashGrowBatchesFinish Waiting for an elected Parallel Hash participant
689 to decide on future batch growth.
690 HashGrowBatchesReallocate Waiting for an elected Parallel Hash
691 participant to allocate more batches.
692 HashGrowBatchesRepartition Waiting for other Parallel Hash participants
693 to finish repartitioning.
694 HashGrowBucketsElect Waiting to elect a Parallel Hash participant to
695 allocate more buckets.
696 HashGrowBucketsReallocate Waiting for an elected Parallel Hash
697 participant to finish allocating more buckets.
698 HashGrowBucketsReinsert Waiting for other Parallel Hash participants to
699 finish inserting tuples into new buckets.
700 LogicalApplySendData Waiting for a logical replication leader apply
701 process to send data to a parallel apply process.
702 LogicalParallelApplyStateChange Waiting for a logical replication
703 parallel apply process to change state.
704 LogicalSyncData Waiting for a logical replication remote server to send
705 data for initial table synchronization.
706 LogicalSyncStateChange Waiting for a logical replication remote server
708 MessageQueueInternal Waiting for another process to be attached to a
709 shared message queue.
710 MessageQueuePutMessage Waiting to write a protocol message to a shared
712 MessageQueueReceive Waiting to receive bytes from a shared message
714 MessageQueueSend Waiting to send bytes to a shared message queue.
715 MultixactCreation Waiting for a multixact creation to complete.
716 ParallelBitmapScan Waiting for parallel bitmap scan to become
718 ParallelCreateIndexScan Waiting for parallel CREATE INDEX workers to
720 ParallelFinish Waiting for parallel workers to finish computing.
721 ProcarrayGroupUpdate Waiting for the group leader to clear the
722 transaction ID at transaction end.
723 ProcSignalBarrier Waiting for a barrier event to be processed by all
725 Promote Waiting for standby promotion.
726 RecoveryConflictSnapshot Waiting for recovery conflict resolution for a
728 RecoveryConflictTablespace Waiting for recovery conflict resolution for
729 dropping a tablespace.
730 RecoveryEndCommand Waiting for recovery_end_command to complete.
731 RecoveryPause Waiting for recovery to be resumed.
732 ReplicationOriginDrop Waiting for a replication origin to become
733 inactive so it can be dropped.
734 ReplicationSlotDrop Waiting for a replication slot to become inactive
735 so it can be dropped.
736 RestoreCommand Waiting for restore_command to complete.
737 SafeSnapshot Waiting to obtain a valid snapshot for a READ ONLY
738 DEFERRABLE transaction.
739 SyncRep Waiting for confirmation from a remote server during
740 synchronous replication.
741 WalReceiverExit Waiting for the WAL receiver to exit.
742 WalReceiverWaitStart Waiting for startup process to send initial data
743 for streaming replication.
744 WalSummaryReady Waiting for a new WAL summary to be generated.
745 XactGroupUpdate Waiting for the group leader to update transaction
746 status at transaction end.
748 Table 27.11. Wait Events of Type Lock
749 Lock Wait Event Description
750 advisory Waiting to acquire an advisory user lock.
751 applytransaction Waiting to acquire a lock on a remote transaction
752 being applied by a logical replication subscriber.
753 extend Waiting to extend a relation.
754 frozenid Waiting to update pg_database.datfrozenxid and
755 pg_database.datminmxid.
756 object Waiting to acquire a lock on a non-relation database object.
757 page Waiting to acquire a lock on a page of a relation.
758 relation Waiting to acquire a lock on a relation.
759 spectoken Waiting to acquire a speculative insertion lock.
760 transactionid Waiting for a transaction to finish.
761 tuple Waiting to acquire a lock on a tuple.
762 userlock Waiting to acquire a user lock.
763 virtualxid Waiting to acquire a virtual transaction ID lock; see
766 Table 27.12. Wait Events of Type Lwlock
767 LWLock Wait Event Description
768 AddinShmemInit Waiting to manage an extension's space allocation in
770 AioUringCompletion Waiting for another process to complete IO via
772 AioWorkerSubmissionQueue Waiting to access AIO worker submission queue.
773 AutoFile Waiting to update the postgresql.auto.conf file.
774 Autovacuum Waiting to read or update the current state of autovacuum
776 AutovacuumSchedule Waiting to ensure that a table selected for
777 autovacuum still needs vacuuming.
778 BackgroundWorker Waiting to read or update background worker state.
779 BtreeVacuum Waiting to read or update vacuum-related information for a
781 BufferContent Waiting to access a data page in memory.
782 BufferMapping Waiting to associate a data block with a buffer in the
784 CheckpointerComm Waiting to manage fsync requests.
785 CommitTs Waiting to read or update the last value set for a transaction
787 CommitTsBuffer Waiting for I/O on a commit timestamp SLRU buffer.
788 CommitTsSLRU Waiting to access the commit timestamp SLRU cache.
789 ControlFile Waiting to read or update the pg_control file or create a
791 DSMRegistry Waiting to read or update the dynamic shared memory
793 DSMRegistryDSA Waiting to access dynamic shared memory registry's
794 dynamic shared memory allocator.
795 DSMRegistryHash Waiting to access dynamic shared memory registry's
797 DynamicSharedMemoryControl Waiting to read or update dynamic shared
798 memory allocation information.
799 InjectionPoint Waiting to read or update information related to
801 LockFastPath Waiting to read or update a process' fast-path lock
803 LockManager Waiting to read or update information about “heavyweight”
805 LogicalRepLauncherDSA Waiting to access logical replication launcher's
806 dynamic shared memory allocator.
807 LogicalRepLauncherHash Waiting to access logical replication launcher's
809 LogicalRepWorker Waiting to read or update the state of logical
811 MultiXactGen Waiting to read or update shared multixact state.
812 MultiXactMemberBuffer Waiting for I/O on a multixact member SLRU
814 MultiXactMemberSLRU Waiting to access the multixact member SLRU cache.
815 MultiXactOffsetBuffer Waiting for I/O on a multixact offset SLRU
817 MultiXactOffsetSLRU Waiting to access the multixact offset SLRU cache.
818 MultiXactTruncation Waiting to read or truncate multixact information.
819 NotifyBuffer Waiting for I/O on a NOTIFY message SLRU buffer.
820 NotifyQueue Waiting to read or update NOTIFY messages.
821 NotifyQueueTail Waiting to update limit on NOTIFY message storage.
822 NotifySLRU Waiting to access the NOTIFY message SLRU cache.
823 OidGen Waiting to allocate a new OID.
824 ParallelAppend Waiting to choose the next subplan during Parallel
825 Append plan execution.
826 ParallelBtreeScan Waiting to synchronize workers during Parallel B-tree
828 ParallelHashJoin Waiting to synchronize workers during Parallel Hash
830 ParallelQueryDSA Waiting for parallel query dynamic shared memory
832 ParallelVacuumDSA Waiting for parallel vacuum dynamic shared memory
834 PerSessionDSA Waiting for parallel query dynamic shared memory
836 PerSessionRecordType Waiting to access a parallel query's information
837 about composite types.
838 PerSessionRecordTypmod Waiting to access a parallel query's information
839 about type modifiers that identify anonymous record types.
840 PerXactPredicateList Waiting to access the list of predicate locks held
841 by the current serializable transaction during a parallel query.
842 PgStatsData Waiting for shared memory stats data access.
843 PgStatsDSA Waiting for stats dynamic shared memory allocator access.
844 PgStatsHash Waiting for stats shared memory hash table access.
845 PredicateLockManager Waiting to access predicate lock information used
846 by serializable transactions.
847 ProcArray Waiting to access the shared per-process data structures
848 (typically, to get a snapshot or report a session's transaction ID).
849 RelationMapping Waiting to read or update a pg_filenode.map file (used
850 to track the filenode assignments of certain system catalogs).
851 RelCacheInit Waiting to read or update a pg_internal.init relation
852 cache initialization file.
853 ReplicationOrigin Waiting to create, drop or use a replication origin.
854 ReplicationOriginState Waiting to read or update the progress of one
856 ReplicationSlotAllocation Waiting to allocate or free a replication
858 ReplicationSlotControl Waiting to read or update replication slot
860 ReplicationSlotIO Waiting for I/O on a replication slot.
861 SerialBuffer Waiting for I/O on a serializable transaction conflict
863 SerialControl Waiting to read or update shared pg_serial state.
864 SerializableFinishedList Waiting to access the list of finished
865 serializable transactions.
866 SerializablePredicateList Waiting to access the list of predicate locks
867 held by serializable transactions.
868 SerializableXactHash Waiting to read or update information about
869 serializable transactions.
870 SerialSLRU Waiting to access the serializable transaction conflict SLRU
872 SharedTidBitmap Waiting to access a shared TID bitmap during a parallel
874 SharedTupleStore Waiting to access a shared tuple store during parallel
876 ShmemIndex Waiting to find or allocate space in shared memory.
877 SInvalRead Waiting to retrieve messages from the shared catalog
879 SInvalWrite Waiting to add a message to the shared catalog invalidation
881 SubtransBuffer Waiting for I/O on a sub-transaction SLRU buffer.
882 SubtransSLRU Waiting to access the sub-transaction SLRU cache.
883 SyncRep Waiting to read or update information about the state of
884 synchronous replication.
885 SyncScan Waiting to select the starting location of a synchronized
887 TablespaceCreate Waiting to create or drop a tablespace.
888 TwoPhaseState Waiting to read or update the state of prepared
890 WaitEventCustom Waiting to read or update custom wait events
892 WALBufMapping Waiting to replace a page in WAL buffers.
893 WALInsert Waiting to insert WAL data into a memory buffer.
894 WALSummarizer Waiting to read or update WAL summarization state.
895 WALWrite Waiting for WAL buffers to be written to disk.
896 WrapLimitsVacuum Waiting to update limits on transaction id and
897 multixact consumption.
898 XactBuffer Waiting for I/O on a transaction status SLRU buffer.
899 XactSLRU Waiting to access the transaction status SLRU cache.
900 XactTruncation Waiting to execute pg_xact_status or update the oldest
901 transaction ID available to it.
902 XidGen Waiting to allocate a new transaction ID.
904 Table 27.13. Wait Events of Type Timeout
905 Timeout Wait Event Description
906 BaseBackupThrottle Waiting during base backup when throttling activity.
907 CheckpointWriteDelay Waiting between writes while performing a
909 PgSleep Waiting due to a call to pg_sleep or a sibling function.
910 RecoveryApplyDelay Waiting to apply WAL during recovery because of a
912 RecoveryRetrieveRetryInterval Waiting during recovery when WAL data is
913 not available from any source (pg_wal, archive or stream).
914 RegisterSyncRequest Waiting while sending synchronization requests to
915 the checkpointer, because the request queue is full.
916 SpinDelay Waiting while acquiring a contended spinlock.
917 VacuumDelay Waiting in a cost-based vacuum delay point.
918 VacuumTruncate Waiting to acquire an exclusive lock to truncate off any
919 empty pages at the end of a table vacuumed.
920 WalSummarizerError Waiting after a WAL summarizer error.
922 Here are examples of how wait events can be viewed:
923 SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i
925 pid | wait_event_type | wait_event
926 ------+-----------------+------------
927 2540 | Lock | relation
928 6644 | LWLock | ProcArray
931 SELECT a.pid, a.wait_event, w.description
932 FROM pg_stat_activity a JOIN
933 pg_wait_events w ON (a.wait_event_type = w.type AND
934 a.wait_event = w.name)
935 WHERE a.wait_event is NOT NULL and a.state = 'active';
936 -[ RECORD 1 ]------------------------------------------------------------------
938 wait_event | WALInitSync
939 description | Waiting for a newly initialized WAL file to reach durable storage
943 Extensions can add Extension, InjectionPoint, and LWLock events to the
944 lists shown in Table 27.8 and Table 27.12. In some cases, the name of
945 an LWLock assigned by an extension will not be available in all server
946 processes. It might be reported as just “extension” rather than the
947 extension-assigned name.
949 27.2.4. pg_stat_replication #
951 The pg_stat_replication view will contain one row per WAL sender
952 process, showing statistics about replication to that sender's
953 connected standby server. Only directly connected standbys are listed;
954 no information is available about downstream standby servers.
956 Table 27.14. pg_stat_replication View
964 Process ID of a WAL sender process
968 OID of the user logged into this WAL sender process
972 Name of the user logged into this WAL sender process
974 application_name text
976 Name of the application that is connected to this WAL sender
980 IP address of the client connected to this WAL sender. If this field is
981 null, it indicates that the client is connected via a Unix socket on
986 Host name of the connected client, as reported by a reverse DNS lookup
987 of client_addr. This field will only be non-null for IP connections,
988 and only when log_hostname is enabled.
992 TCP port number that the client is using for communication with this
993 WAL sender, or -1 if a Unix socket is used
995 backend_start timestamp with time zone
997 Time when this process was started, i.e., when the client connected to
1002 This standby's xmin horizon reported by hot_standby_feedback.
1006 Current WAL sender state. Possible values are:
1007 * startup: This WAL sender is starting up.
1008 * catchup: This WAL sender's connected standby is catching up with
1010 * streaming: This WAL sender is streaming changes after its connected
1011 standby server has caught up with the primary.
1012 * backup: This WAL sender is sending a backup.
1013 * stopping: This WAL sender is stopping.
1017 Last write-ahead log location sent on this connection
1021 Last write-ahead log location written to disk by this standby server
1025 Last write-ahead log location flushed to disk by this standby server
1029 Last write-ahead log location replayed into the database on this
1034 Time elapsed between flushing recent WAL locally and receiving
1035 notification that this standby server has written it (but not yet
1036 flushed it or applied it). This can be used to gauge the delay that
1037 synchronous_commit level remote_write incurred while committing if this
1038 server was configured as a synchronous standby.
1042 Time elapsed between flushing recent WAL locally and receiving
1043 notification that this standby server has written and flushed it (but
1044 not yet applied it). This can be used to gauge the delay that
1045 synchronous_commit level on incurred while committing if this server
1046 was configured as a synchronous standby.
1050 Time elapsed between flushing recent WAL locally and receiving
1051 notification that this standby server has written, flushed and applied
1052 it. This can be used to gauge the delay that synchronous_commit level
1053 remote_apply incurred while committing if this server was configured as
1054 a synchronous standby.
1056 sync_priority integer
1058 Priority of this standby server for being chosen as the synchronous
1059 standby in a priority-based synchronous replication. This has no effect
1060 in a quorum-based synchronous replication.
1064 Synchronous state of this standby server. Possible values are:
1065 * async: This standby server is asynchronous.
1066 * potential: This standby server is now asynchronous, but can
1067 potentially become synchronous if one of current synchronous ones
1069 * sync: This standby server is synchronous.
1070 * quorum: This standby server is considered as a candidate for quorum
1073 reply_time timestamp with time zone
1075 Send time of last reply message received from standby server
1077 The lag times reported in the pg_stat_replication view are measurements
1078 of the time taken for recent WAL to be written, flushed and replayed
1079 and for the sender to know about it. These times represent the commit
1080 delay that was (or would have been) introduced by each synchronous
1081 commit level, if the remote server was configured as a synchronous
1082 standby. For an asynchronous standby, the replay_lag column
1083 approximates the delay before recent transactions became visible to
1084 queries. If the standby server has entirely caught up with the sending
1085 server and there is no more WAL activity, the most recently measured
1086 lag times will continue to be displayed for a short time and then show
1089 Lag times work automatically for physical replication. Logical decoding
1090 plugins may optionally emit tracking messages; if they do not, the
1091 tracking mechanism will simply display NULL lag.
1095 The reported lag times are not predictions of how long it will take for
1096 the standby to catch up with the sending server assuming the current
1097 rate of replay. Such a system would show similar times while new WAL is
1098 being generated, but would differ when the sender becomes idle. In
1099 particular, when the standby has caught up completely,
1100 pg_stat_replication shows the time taken to write, flush and replay the
1101 most recent reported WAL location rather than zero as some users might
1102 expect. This is consistent with the goal of measuring synchronous
1103 commit and transaction visibility delays for recent write transactions.
1104 To reduce confusion for users expecting a different model of lag, the
1105 lag columns revert to NULL after a short time on a fully replayed idle
1106 system. Monitoring systems should choose whether to represent this as
1107 missing data, zero or continue to display the last known value.
1109 27.2.5. pg_stat_replication_slots #
1111 The pg_stat_replication_slots view will contain one row per logical
1112 replication slot, showing statistics about its usage.
1114 Table 27.15. pg_stat_replication_slots View
1122 A unique, cluster-wide identifier for the replication slot
1126 Number of transactions spilled to disk once the memory used by logical
1127 decoding to decode changes from WAL has exceeded
1128 logical_decoding_work_mem. The counter gets incremented for both
1129 top-level transactions and subtransactions.
1133 Number of times transactions were spilled to disk while decoding
1134 changes from WAL for this slot. This counter is incremented each time a
1135 transaction is spilled, and the same transaction may be spilled
1140 Amount of decoded transaction data spilled to disk while performing
1141 decoding of changes from WAL for this slot. This and other spill
1142 counters can be used to gauge the I/O which occurred during logical
1143 decoding and allow tuning logical_decoding_work_mem.
1147 Number of in-progress transactions streamed to the decoding output
1148 plugin after the memory used by logical decoding to decode changes from
1149 WAL for this slot has exceeded logical_decoding_work_mem. Streaming
1150 only works with top-level transactions (subtransactions can't be
1151 streamed independently), so the counter is not incremented for
1156 Number of times in-progress transactions were streamed to the decoding
1157 output plugin while decoding changes from WAL for this slot. This
1158 counter is incremented each time a transaction is streamed, and the
1159 same transaction may be streamed multiple times.
1163 Amount of transaction data decoded for streaming in-progress
1164 transactions to the decoding output plugin while decoding changes from
1165 WAL for this slot. This and other streaming counters for this slot can
1166 be used to tune logical_decoding_work_mem.
1170 Number of decoded transactions sent to the decoding output plugin for
1171 this slot. This counts top-level transactions only, and is not
1172 incremented for subtransactions. Note that this includes the
1173 transactions that are streamed and/or spilled.
1177 Amount of transaction data decoded for sending transactions to the
1178 decoding output plugin while decoding changes from WAL for this slot.
1179 Note that this includes data that is streamed and/or spilled.
1181 stats_reset timestamp with time zone
1183 Time at which these statistics were last reset
1185 27.2.6. pg_stat_wal_receiver #
1187 The pg_stat_wal_receiver view will contain only one row, showing
1188 statistics about the WAL receiver from that receiver's connected
1191 Table 27.16. pg_stat_wal_receiver View
1199 Process ID of the WAL receiver process
1203 Activity status of the WAL receiver process
1205 receive_start_lsn pg_lsn
1207 First write-ahead log location used when WAL receiver is started
1209 receive_start_tli integer
1211 First timeline number used when WAL receiver is started
1215 Last write-ahead log location already received and written to disk, but
1216 not flushed. This should not be used for data integrity checks.
1220 Last write-ahead log location already received and flushed to disk, the
1221 initial value of this field being the first log location used when WAL
1224 received_tli integer
1226 Timeline number of last write-ahead log location received and flushed
1227 to disk, the initial value of this field being the timeline number of
1228 the first log location used when WAL receiver is started
1230 last_msg_send_time timestamp with time zone
1232 Send time of last message received from origin WAL sender
1234 last_msg_receipt_time timestamp with time zone
1236 Receipt time of last message received from origin WAL sender
1238 latest_end_lsn pg_lsn
1240 Last write-ahead log location reported to origin WAL sender
1242 latest_end_time timestamp with time zone
1244 Time of last write-ahead log location reported to origin WAL sender
1248 Replication slot name used by this WAL receiver
1252 Host of the PostgreSQL instance this WAL receiver is connected to. This
1253 can be a host name, an IP address, or a directory path if the
1254 connection is via Unix socket. (The path case can be distinguished
1255 because it will always be an absolute path, beginning with /.)
1259 Port number of the PostgreSQL instance this WAL receiver is connected
1264 Connection string used by this WAL receiver, with security-sensitive
1267 27.2.7. pg_stat_recovery_prefetch #
1269 The pg_stat_recovery_prefetch view will contain only one row. The
1270 columns wal_distance, block_distance and io_depth show current values,
1271 and the other columns show cumulative counters that can be reset with
1272 the pg_stat_reset_shared function.
1274 Table 27.17. pg_stat_recovery_prefetch View
1280 stats_reset timestamp with time zone
1282 Time at which these statistics were last reset
1286 Number of blocks prefetched because they were not in the buffer pool
1290 Number of blocks not prefetched because they were already in the buffer
1295 Number of blocks not prefetched because they would be zero-initialized
1299 Number of blocks not prefetched because they didn't exist yet
1303 Number of blocks not prefetched because a full page image was included
1308 Number of blocks not prefetched because they were already recently
1313 How many bytes ahead the prefetcher is looking
1317 How many blocks ahead the prefetcher is looking
1321 How many prefetches have been initiated but are not yet known to have
1324 27.2.8. pg_stat_subscription #
1326 Table 27.18. pg_stat_subscription View
1334 OID of the subscription
1338 Name of the subscription
1342 Type of the subscription worker process. Possible types are apply,
1343 parallel apply, and table synchronization.
1347 Process ID of the subscription worker process
1351 Process ID of the leader apply worker if this process is a parallel
1352 apply worker; NULL if this process is a leader apply worker or a table
1353 synchronization worker
1357 OID of the relation that the worker is synchronizing; NULL for the
1358 leader apply worker and parallel apply workers
1362 Last write-ahead log location received, the initial value of this field
1363 being 0; NULL for parallel apply workers
1365 last_msg_send_time timestamp with time zone
1367 Send time of last message received from origin WAL sender; NULL for
1368 parallel apply workers
1370 last_msg_receipt_time timestamp with time zone
1372 Receipt time of last message received from origin WAL sender; NULL for
1373 parallel apply workers
1375 latest_end_lsn pg_lsn
1377 Last write-ahead log location reported to origin WAL sender; NULL for
1378 parallel apply workers
1380 latest_end_time timestamp with time zone
1382 Time of last write-ahead log location reported to origin WAL sender;
1383 NULL for parallel apply workers
1385 27.2.9. pg_stat_subscription_stats #
1387 The pg_stat_subscription_stats view will contain one row per
1390 Table 27.19. pg_stat_subscription_stats View
1398 OID of the subscription
1402 Name of the subscription
1404 apply_error_count bigint
1406 Number of times an error occurred while applying changes. Note that any
1407 conflict resulting in an apply error will be counted in both
1408 apply_error_count and the corresponding conflict count (e.g., confl_*).
1410 sync_error_count bigint
1412 Number of times an error occurred during the initial table
1415 confl_insert_exists bigint
1417 Number of times a row insertion violated a NOT DEFERRABLE unique
1418 constraint during the application of changes. See insert_exists for
1419 details about this conflict.
1421 confl_update_origin_differs bigint
1423 Number of times an update was applied to a row that had been previously
1424 modified by another source during the application of changes. See
1425 update_origin_differs for details about this conflict.
1427 confl_update_exists bigint
1429 Number of times that an updated row value violated a NOT DEFERRABLE
1430 unique constraint during the application of changes. See update_exists
1431 for details about this conflict.
1433 confl_update_missing bigint
1435 Number of times the tuple to be updated was not found during the
1436 application of changes. See update_missing for details about this
1439 confl_delete_origin_differs bigint
1441 Number of times a delete operation was applied to row that had been
1442 previously modified by another source during the application of
1443 changes. See delete_origin_differs for details about this conflict.
1445 confl_delete_missing bigint
1447 Number of times the tuple to be deleted was not found during the
1448 application of changes. See delete_missing for details about this
1451 confl_multiple_unique_conflicts bigint
1453 Number of times a row insertion or an updated row values violated
1454 multiple NOT DEFERRABLE unique constraints during the application of
1455 changes. See multiple_unique_conflicts for details about this conflict.
1457 stats_reset timestamp with time zone
1459 Time at which these statistics were last reset
1461 27.2.10. pg_stat_ssl #
1463 The pg_stat_ssl view will contain one row per backend or WAL sender
1464 process, showing statistics about SSL usage on this connection. It can
1465 be joined to pg_stat_activity or pg_stat_replication on the pid column
1466 to get more details about the connection.
1468 Table 27.20. pg_stat_ssl View
1476 Process ID of a backend or WAL sender process
1480 True if SSL is used on this connection
1484 Version of SSL in use, or NULL if SSL is not in use on this connection
1488 Name of SSL cipher in use, or NULL if SSL is not in use on this
1493 Number of bits in the encryption algorithm used, or NULL if SSL is not
1494 used on this connection
1498 Distinguished Name (DN) field from the client certificate used, or NULL
1499 if no client certificate was supplied or if SSL is not in use on this
1500 connection. This field is truncated if the DN field is longer than
1501 NAMEDATALEN (64 characters in a standard build).
1503 client_serial numeric
1505 Serial number of the client certificate, or NULL if no client
1506 certificate was supplied or if SSL is not in use on this connection.
1507 The combination of certificate serial number and certificate issuer
1508 uniquely identifies a certificate (unless the issuer erroneously reuses
1513 DN of the issuer of the client certificate, or NULL if no client
1514 certificate was supplied or if SSL is not in use on this connection.
1515 This field is truncated like client_dn.
1517 27.2.11. pg_stat_gssapi #
1519 The pg_stat_gssapi view will contain one row per backend, showing
1520 information about GSSAPI usage on this connection. It can be joined to
1521 pg_stat_activity or pg_stat_replication on the pid column to get more
1522 details about the connection.
1524 Table 27.21. pg_stat_gssapi View
1532 Process ID of a backend
1534 gss_authenticated boolean
1536 True if GSSAPI authentication was used for this connection
1540 Principal used to authenticate this connection, or NULL if GSSAPI was
1541 not used to authenticate this connection. This field is truncated if
1542 the principal is longer than NAMEDATALEN (64 characters in a standard
1547 True if GSSAPI encryption is in use on this connection
1549 credentials_delegated boolean
1551 True if GSSAPI credentials were delegated on this connection.
1553 27.2.12. pg_stat_archiver #
1555 The pg_stat_archiver view will always have a single row, containing
1556 data about the archiver process of the cluster.
1558 Table 27.22. pg_stat_archiver View
1564 archived_count bigint
1566 Number of WAL files that have been successfully archived
1568 last_archived_wal text
1570 Name of the WAL file most recently successfully archived
1572 last_archived_time timestamp with time zone
1574 Time of the most recent successful archive operation
1578 Number of failed attempts for archiving WAL files
1580 last_failed_wal text
1582 Name of the WAL file of the most recent failed archival operation
1584 last_failed_time timestamp with time zone
1586 Time of the most recent failed archival operation
1588 stats_reset timestamp with time zone
1590 Time at which these statistics were last reset
1592 Normally, WAL files are archived in order, oldest to newest, but that
1593 is not guaranteed, and does not hold under special circumstances like
1594 when promoting a standby or after crash recovery. Therefore it is not
1595 safe to assume that all files older than last_archived_wal have also
1596 been successfully archived.
1598 27.2.13. pg_stat_io #
1600 The pg_stat_io view will contain one row for each combination of
1601 backend type, target I/O object, and I/O context, showing cluster-wide
1602 I/O statistics. Combinations which do not make sense are omitted.
1604 Currently, I/O on relations (e.g. tables, indexes) and WAL activity are
1605 tracked. However, relation I/O which bypasses shared buffers (e.g. when
1606 moving a table from one tablespace to another) is currently not
1609 Table 27.23. pg_stat_io View
1617 Type of backend (e.g. background worker, autovacuum worker). See
1618 pg_stat_activity for more information on backend_types. Some
1619 backend_types do not accumulate I/O operation statistics and will not
1620 be included in the view.
1624 Target object of an I/O operation. Possible values are:
1625 * relation: Permanent relations.
1626 * temp relation: Temporary relations.
1627 * wal: Write Ahead Logs.
1631 The context of an I/O operation. Possible values are:
1632 * normal: The default or standard context for a type of I/O
1633 operation. For example, by default, relation data is read into and
1634 written out from shared buffers. Thus, reads and writes of relation
1635 data to and from shared buffers are tracked in context normal.
1636 * init: I/O operations performed while creating the WAL segments are
1637 tracked in context init.
1638 * vacuum: I/O operations performed outside of shared buffers while
1639 vacuuming and analyzing permanent relations. Temporary table
1640 vacuums use the same local buffer pool as other temporary table I/O
1641 operations and are tracked in context normal.
1642 * bulkread: Certain large read I/O operations done outside of shared
1643 buffers, for example, a sequential scan of a large table.
1644 * bulkwrite: Certain large write I/O operations done outside of
1645 shared buffers, such as COPY.
1649 Number of read operations.
1653 The total size of read operations in bytes.
1655 read_time double precision
1657 Time spent waiting for read operations in milliseconds (if
1658 track_io_timing is enabled and object is not wal, or if
1659 track_wal_io_timing is enabled and object is wal, otherwise zero)
1663 Number of write operations.
1667 The total size of write operations in bytes.
1669 write_time double precision
1671 Time spent waiting for write operations in milliseconds (if
1672 track_io_timing is enabled and object is not wal, or if
1673 track_wal_io_timing is enabled and object is wal, otherwise zero)
1677 Number of units of size BLCKSZ (typically 8kB) which the process
1678 requested the kernel write out to permanent storage.
1680 writeback_time double precision
1682 Time spent waiting for writeback operations in milliseconds (if
1683 track_io_timing is enabled, otherwise zero). This includes the time
1684 spent queueing write-out requests and, potentially, the time spent to
1685 write out the dirty data.
1689 Number of relation extend operations.
1691 extend_bytes numeric
1693 The total size of relation extend operations in bytes.
1695 extend_time double precision
1697 Time spent waiting for extend operations in milliseconds. (if
1698 track_io_timing is enabled and object is not wal, or if
1699 track_wal_io_timing is enabled and object is wal, otherwise zero)
1703 The number of times a desired block was found in a shared buffer.
1707 Number of times a block has been written out from a shared or local
1708 buffer in order to make it available for another use.
1710 In context normal, this counts the number of times a block was evicted
1711 from a buffer and replaced with another block. In contexts bulkwrite,
1712 bulkread, and vacuum, this counts the number of times a block was
1713 evicted from shared buffers in order to add the shared buffer to a
1714 separate, size-limited ring buffer for use in a bulk I/O operation.
1718 The number of times an existing buffer in a size-limited ring buffer
1719 outside of shared buffers was reused as part of an I/O operation in the
1720 bulkread, bulkwrite, or vacuum contexts.
1724 Number of fsync calls. These are only tracked in context normal.
1726 fsync_time double precision
1728 Time spent waiting for fsync operations in milliseconds (if
1729 track_io_timing is enabled and object is not wal, or if
1730 track_wal_io_timing is enabled and object is wal, otherwise zero)
1732 stats_reset timestamp with time zone
1734 Time at which these statistics were last reset.
1736 Some backend types never perform I/O operations on some I/O objects
1737 and/or in some I/O contexts. These rows are omitted from the view. For
1738 example, the checkpointer does not checkpoint temporary tables, so
1739 there will be no rows for backend_type checkpointer and object temp
1742 In addition, some I/O operations will never be performed either by
1743 certain backend types or on certain I/O objects and/or in certain I/O
1744 contexts. These cells will be NULL. For example, temporary tables are
1745 not fsynced, so fsyncs will be NULL for object temp relation. Also, the
1746 background writer does not perform reads, so reads will be NULL in rows
1747 for backend_type background writer.
1749 For the object wal, fsyncs and fsync_time track the fsync activity of
1750 WAL files done in issue_xlog_fsync. writes and write_time track the
1751 write activity of WAL files done in XLogWrite. See Section 28.5 for
1754 pg_stat_io can be used to inform database tuning. For example:
1755 * A high evictions count can indicate that shared buffers should be
1757 * Client backends rely on the checkpointer to ensure data is
1758 persisted to permanent storage. Large numbers of fsyncs by client
1759 backends could indicate a misconfiguration of shared buffers or of
1760 the checkpointer. More information on configuring the checkpointer
1761 can be found in Section 28.5.
1762 * Normally, client backends should be able to rely on auxiliary
1763 processes like the checkpointer and the background writer to write
1764 out dirty data as much as possible. Large numbers of writes by
1765 client backends could indicate a misconfiguration of shared buffers
1766 or of the checkpointer. More information on configuring the
1767 checkpointer can be found in Section 28.5.
1771 Columns tracking I/O wait time will only be non-zero when
1772 track_io_timing is enabled. The user should be careful when referencing
1773 these columns in combination with their corresponding I/O operations in
1774 case track_io_timing was not enabled for the entire time since the last
1777 27.2.14. pg_stat_bgwriter #
1779 The pg_stat_bgwriter view will always have a single row, containing
1780 data about the background writer of the cluster.
1782 Table 27.24. pg_stat_bgwriter View
1788 buffers_clean bigint
1790 Number of buffers written by the background writer
1792 maxwritten_clean bigint
1794 Number of times the background writer stopped a cleaning scan because
1795 it had written too many buffers
1797 buffers_alloc bigint
1799 Number of buffers allocated
1801 stats_reset timestamp with time zone
1803 Time at which these statistics were last reset
1805 27.2.15. pg_stat_checkpointer #
1807 The pg_stat_checkpointer view will always have a single row, containing
1808 data about the checkpointer process of the cluster.
1810 Table 27.25. pg_stat_checkpointer View
1818 Number of scheduled checkpoints due to timeout
1820 num_requested bigint
1822 Number of requested checkpoints
1826 Number of checkpoints that have been performed
1828 restartpoints_timed bigint
1830 Number of scheduled restartpoints due to timeout or after a failed
1831 attempt to perform it
1833 restartpoints_req bigint
1835 Number of requested restartpoints
1837 restartpoints_done bigint
1839 Number of restartpoints that have been performed
1841 write_time double precision
1843 Total amount of time that has been spent in the portion of processing
1844 checkpoints and restartpoints where files are written to disk, in
1847 sync_time double precision
1849 Total amount of time that has been spent in the portion of processing
1850 checkpoints and restartpoints where files are synchronized to disk, in
1853 buffers_written bigint
1855 Number of shared buffers written during checkpoints and restartpoints
1859 Number of SLRU buffers written during checkpoints and restartpoints
1861 stats_reset timestamp with time zone
1863 Time at which these statistics were last reset
1865 Checkpoints may be skipped if the server has been idle since the last
1866 one. num_timed and num_requested count both completed and skipped
1867 checkpoints, while num_done tracks only the completed ones. Similarly,
1868 restartpoints may be skipped if the last replayed checkpoint record is
1869 already the last restartpoint. restartpoints_timed and
1870 restartpoints_req count both completed and skipped restartpoints, while
1871 restartpoints_done tracks only the completed ones.
1873 27.2.16. pg_stat_wal #
1875 The pg_stat_wal view will always have a single row, containing data
1876 about WAL activity of the cluster.
1878 Table 27.26. pg_stat_wal View
1886 Total number of WAL records generated
1890 Total number of WAL full page images generated
1894 Total amount of WAL generated in bytes
1896 wal_buffers_full bigint
1898 Number of times WAL data was written to disk because WAL buffers became
1901 stats_reset timestamp with time zone
1903 Time at which these statistics were last reset
1905 27.2.17. pg_stat_database #
1907 The pg_stat_database view will contain one row for each database in the
1908 cluster, plus one for shared objects, showing database-wide statistics.
1910 Table 27.27. pg_stat_database View
1918 OID of this database, or 0 for objects belonging to a shared relation
1922 Name of this database, or NULL for shared objects.
1926 Number of backends currently connected to this database, or NULL for
1927 shared objects. This is the only column in this view that returns a
1928 value reflecting current state; all other columns return the
1929 accumulated values since the last reset.
1933 Number of transactions in this database that have been committed
1935 xact_rollback bigint
1937 Number of transactions in this database that have been rolled back
1941 Number of disk blocks read in this database
1945 Number of times disk blocks were found already in the buffer cache, so
1946 that a read was not necessary (this only includes hits in the
1947 PostgreSQL buffer cache, not the operating system's file system cache)
1951 Number of live rows fetched by sequential scans and index entries
1952 returned by index scans in this database
1956 Number of live rows fetched by index scans in this database
1960 Number of rows inserted by queries in this database
1964 Number of rows updated by queries in this database
1968 Number of rows deleted by queries in this database
1972 Number of queries canceled due to conflicts with recovery in this
1973 database. (Conflicts occur only on standby servers; see
1974 pg_stat_database_conflicts for details.)
1978 Number of temporary files created by queries in this database. All
1979 temporary files are counted, regardless of why the temporary file was
1980 created (e.g., sorting or hashing), and regardless of the
1981 log_temp_files setting.
1985 Total amount of data written to temporary files by queries in this
1986 database. All temporary files are counted, regardless of why the
1987 temporary file was created, and regardless of the log_temp_files
1992 Number of deadlocks detected in this database
1994 checksum_failures bigint
1996 Number of data page checksum failures detected in this database (or on
1997 a shared object), or NULL if data checksums are disabled.
1999 checksum_last_failure timestamp with time zone
2001 Time at which the last data page checksum failure was detected in this
2002 database (or on a shared object), or NULL if data checksums are
2005 blk_read_time double precision
2007 Time spent reading data file blocks by backends in this database, in
2008 milliseconds (if track_io_timing is enabled, otherwise zero)
2010 blk_write_time double precision
2012 Time spent writing data file blocks by backends in this database, in
2013 milliseconds (if track_io_timing is enabled, otherwise zero)
2015 session_time double precision
2017 Time spent by database sessions in this database, in milliseconds (note
2018 that statistics are only updated when the state of a session changes,
2019 so if sessions have been idle for a long time, this idle time won't be
2022 active_time double precision
2024 Time spent executing SQL statements in this database, in milliseconds
2025 (this corresponds to the states active and fastpath function call in
2028 idle_in_transaction_time double precision
2030 Time spent idling while in a transaction in this database, in
2031 milliseconds (this corresponds to the states idle in transaction and
2032 idle in transaction (aborted) in pg_stat_activity)
2036 Total number of sessions established to this database
2038 sessions_abandoned bigint
2040 Number of database sessions to this database that were terminated
2041 because connection to the client was lost
2043 sessions_fatal bigint
2045 Number of database sessions to this database that were terminated by
2048 sessions_killed bigint
2050 Number of database sessions to this database that were terminated by
2051 operator intervention
2053 parallel_workers_to_launch bigint
2055 Number of parallel workers planned to be launched by queries on this
2058 parallel_workers_launched bigint
2060 Number of parallel workers launched by queries on this database
2062 stats_reset timestamp with time zone
2064 Time at which these statistics were last reset
2066 27.2.18. pg_stat_database_conflicts #
2068 The pg_stat_database_conflicts view will contain one row per database,
2069 showing database-wide statistics about query cancels occurring due to
2070 conflicts with recovery on standby servers. This view will only contain
2071 information on standby servers, since conflicts do not occur on primary
2074 Table 27.28. pg_stat_database_conflicts View
2086 Name of this database
2088 confl_tablespace bigint
2090 Number of queries in this database that have been canceled due to
2095 Number of queries in this database that have been canceled due to lock
2098 confl_snapshot bigint
2100 Number of queries in this database that have been canceled due to old
2103 confl_bufferpin bigint
2105 Number of queries in this database that have been canceled due to
2108 confl_deadlock bigint
2110 Number of queries in this database that have been canceled due to
2113 confl_active_logicalslot bigint
2115 Number of uses of logical slots in this database that have been
2116 canceled due to old snapshots or too low a wal_level on the primary
2118 27.2.19. pg_stat_all_tables #
2120 The pg_stat_all_tables view will contain one row for each table in the
2121 current database (including TOAST tables), showing statistics about
2122 accesses to that specific table. The pg_stat_user_tables and
2123 pg_stat_sys_tables views contain the same information, but filtered to
2124 only show user and system tables respectively.
2126 Table 27.29. pg_stat_all_tables View
2138 Name of the schema that this table is in
2146 Number of sequential scans initiated on this table
2148 last_seq_scan timestamp with time zone
2150 The time of the last sequential scan on this table, based on the most
2151 recent transaction stop time
2155 Number of live rows fetched by sequential scans
2159 Number of index scans initiated on this table
2161 last_idx_scan timestamp with time zone
2163 The time of the last index scan on this table, based on the most recent
2164 transaction stop time
2166 idx_tup_fetch bigint
2168 Number of live rows fetched by index scans
2172 Total number of rows inserted
2176 Total number of rows updated. (This includes row updates counted in
2177 n_tup_hot_upd and n_tup_newpage_upd, and remaining non-HOT updates.)
2181 Total number of rows deleted
2183 n_tup_hot_upd bigint
2185 Number of rows HOT updated. These are updates where no successor
2186 versions are required in indexes.
2188 n_tup_newpage_upd bigint
2190 Number of rows updated where the successor version goes onto a new heap
2191 page, leaving behind an original version with a t_ctid field that
2192 points to a different heap page. These are always non-HOT updates.
2196 Estimated number of live rows
2200 Estimated number of dead rows
2202 n_mod_since_analyze bigint
2204 Estimated number of rows modified since this table was last analyzed
2206 n_ins_since_vacuum bigint
2208 Estimated number of rows inserted since this table was last vacuumed
2209 (not counting VACUUM FULL)
2211 last_vacuum timestamp with time zone
2213 Last time at which this table was manually vacuumed (not counting
2216 last_autovacuum timestamp with time zone
2218 Last time at which this table was vacuumed by the autovacuum daemon
2220 last_analyze timestamp with time zone
2222 Last time at which this table was manually analyzed
2224 last_autoanalyze timestamp with time zone
2226 Last time at which this table was analyzed by the autovacuum daemon
2230 Number of times this table has been manually vacuumed (not counting
2233 autovacuum_count bigint
2235 Number of times this table has been vacuumed by the autovacuum daemon
2237 analyze_count bigint
2239 Number of times this table has been manually analyzed
2241 autoanalyze_count bigint
2243 Number of times this table has been analyzed by the autovacuum daemon
2245 total_vacuum_time double precision
2247 Total time this table has been manually vacuumed, in milliseconds (not
2248 counting VACUUM FULL). (This includes the time spent sleeping due to
2251 total_autovacuum_time double precision
2253 Total time this table has been vacuumed by the autovacuum daemon, in
2254 milliseconds. (This includes the time spent sleeping due to cost-based
2257 total_analyze_time double precision
2259 Total time this table has been manually analyzed, in milliseconds.
2260 (This includes the time spent sleeping due to cost-based delays.)
2262 total_autoanalyze_time double precision
2264 Total time this table has been analyzed by the autovacuum daemon, in
2265 milliseconds. (This includes the time spent sleeping due to cost-based
2268 27.2.20. pg_stat_all_indexes #
2270 The pg_stat_all_indexes view will contain one row for each index in the
2271 current database, showing statistics about accesses to that specific
2272 index. The pg_stat_user_indexes and pg_stat_sys_indexes views contain
2273 the same information, but filtered to only show user and system indexes
2276 Table 27.30. pg_stat_all_indexes View
2284 OID of the table for this index
2292 Name of the schema this index is in
2296 Name of the table for this index
2304 Number of index scans initiated on this index
2306 last_idx_scan timestamp with time zone
2308 The time of the last scan on this index, based on the most recent
2309 transaction stop time
2313 Number of index entries returned by scans on this index
2315 idx_tup_fetch bigint
2317 Number of live table rows fetched by simple index scans using this
2320 Indexes can be used by simple index scans, “bitmap” index scans, and
2321 the optimizer. In a bitmap scan the output of several indexes can be
2322 combined via AND or OR rules, so it is difficult to associate
2323 individual heap row fetches with specific indexes when a bitmap scan is
2324 used. Therefore, a bitmap scan increments the
2325 pg_stat_all_indexes.idx_tup_read count(s) for the index(es) it uses,
2326 and it increments the pg_stat_all_tables.idx_tup_fetch count for the
2327 table, but it does not affect pg_stat_all_indexes.idx_tup_fetch. The
2328 optimizer also accesses indexes to check for supplied constants whose
2329 values are outside the recorded range of the optimizer statistics
2330 because the optimizer statistics might be stale.
2334 The idx_tup_read and idx_tup_fetch counts can be different even without
2335 any use of bitmap scans, because idx_tup_read counts index entries
2336 retrieved from the index while idx_tup_fetch counts live rows fetched
2337 from the table. The latter will be less if any dead or
2338 not-yet-committed rows are fetched using the index, or if any heap
2339 fetches are avoided by means of an index-only scan.
2343 Index scans may sometimes perform multiple index searches per
2344 execution. Each index search increments pg_stat_all_indexes.idx_scan,
2345 so it's possible for the count of index scans to significantly exceed
2346 the total number of index scan executor node executions.
2348 This can happen with queries that use certain SQL constructs to search
2349 for rows matching any value out of a list or array of multiple scalar
2350 values (see Section 9.25). It can also happen to queries with a
2351 column_name = value1 OR column_name = value2 ... construct, though only
2352 when the optimizer transforms the construct into an equivalent
2353 multi-valued array representation. Similarly, when B-tree index scans
2354 use the skip scan optimization, an index search is performed each time
2355 the scan is repositioned to the next index leaf page that might have
2356 matching tuples (see Section 11.3).
2360 EXPLAIN ANALYZE outputs the total number of index searches performed by
2361 each index scan node. See Section 14.1.2 for an example demonstrating
2364 27.2.21. pg_statio_all_tables #
2366 The pg_statio_all_tables view will contain one row for each table in
2367 the current database (including TOAST tables), showing statistics about
2368 I/O on that specific table. The pg_statio_user_tables and
2369 pg_statio_sys_tables views contain the same information, but filtered
2370 to only show user and system tables respectively.
2372 Table 27.31. pg_statio_all_tables View
2384 Name of the schema that this table is in
2390 heap_blks_read bigint
2392 Number of disk blocks read from this table
2394 heap_blks_hit bigint
2396 Number of buffer hits in this table
2398 idx_blks_read bigint
2400 Number of disk blocks read from all indexes on this table
2404 Number of buffer hits in all indexes on this table
2406 toast_blks_read bigint
2408 Number of disk blocks read from this table's TOAST table (if any)
2410 toast_blks_hit bigint
2412 Number of buffer hits in this table's TOAST table (if any)
2414 tidx_blks_read bigint
2416 Number of disk blocks read from this table's TOAST table indexes (if
2419 tidx_blks_hit bigint
2421 Number of buffer hits in this table's TOAST table indexes (if any)
2423 27.2.22. pg_statio_all_indexes #
2425 The pg_statio_all_indexes view will contain one row for each index in
2426 the current database, showing statistics about I/O on that specific
2427 index. The pg_statio_user_indexes and pg_statio_sys_indexes views
2428 contain the same information, but filtered to only show user and system
2429 indexes respectively.
2431 Table 27.32. pg_statio_all_indexes View
2439 OID of the table for this index
2447 Name of the schema this index is in
2451 Name of the table for this index
2457 idx_blks_read bigint
2459 Number of disk blocks read from this index
2463 Number of buffer hits in this index
2465 27.2.23. pg_statio_all_sequences #
2467 The pg_statio_all_sequences view will contain one row for each sequence
2468 in the current database, showing statistics about I/O on that specific
2471 Table 27.33. pg_statio_all_sequences View
2483 Name of the schema this sequence is in
2487 Name of this sequence
2491 Number of disk blocks read from this sequence
2495 Number of buffer hits in this sequence
2497 27.2.24. pg_stat_user_functions #
2499 The pg_stat_user_functions view will contain one row for each tracked
2500 function, showing statistics about executions of that function. The
2501 track_functions parameter controls exactly which functions are tracked.
2503 Table 27.34. pg_stat_user_functions View
2515 Name of the schema this function is in
2519 Name of this function
2523 Number of times this function has been called
2525 total_time double precision
2527 Total time spent in this function and all other functions called by it,
2530 self_time double precision
2532 Total time spent in this function itself, not including other functions
2533 called by it, in milliseconds
2535 27.2.25. pg_stat_slru #
2537 PostgreSQL accesses certain on-disk information via SLRU (simple
2538 least-recently-used) caches. The pg_stat_slru view will contain one row
2539 for each tracked SLRU cache, showing statistics about access to cached
2542 For each SLRU cache that's part of the core server, there is a
2543 configuration parameter that controls its size, with the suffix
2546 Table 27.35. pg_stat_slru View
2558 Number of blocks zeroed during initializations
2562 Number of times disk blocks were found already in the SLRU, so that a
2563 read was not necessary (this only includes hits in the SLRU, not the
2564 operating system's file system cache)
2568 Number of disk blocks read for this SLRU
2572 Number of disk blocks written for this SLRU
2576 Number of blocks checked for existence for this SLRU
2580 Number of flushes of dirty data for this SLRU
2584 Number of truncates for this SLRU
2586 stats_reset timestamp with time zone
2588 Time at which these statistics were last reset
2590 27.2.26. Statistics Functions #
2592 Other ways of looking at the statistics can be set up by writing
2593 queries that use the same underlying statistics access functions used
2594 by the standard views shown above. For details such as the functions'
2595 names, consult the definitions of the standard views. (For example, in
2596 psql you could issue \d+ pg_stat_activity.) The access functions for
2597 per-database statistics take a database OID as an argument to identify
2598 which database to report on. The per-table and per-index functions take
2599 a table or index OID. The functions for per-function statistics take a
2600 function OID. Note that only tables, indexes, and functions in the
2601 current database can be seen with these functions.
2603 Additional functions related to the cumulative statistics system are
2604 listed in Table 27.36.
2606 Table 27.36. Additional Statistics Functions
2612 pg_backend_pid () → integer
2614 Returns the process ID of the server process attached to the current
2617 pg_stat_get_backend_io ( integer ) → setof record
2619 Returns I/O statistics about the backend with the specified process ID.
2620 The output fields are exactly the same as the ones in the pg_stat_io
2623 The function does not return I/O statistics for the checkpointer, the
2624 background writer, the startup process and the autovacuum launcher as
2625 they are already visible in the pg_stat_io view and there is only one
2628 pg_stat_get_activity ( integer ) → setof record
2630 Returns a record of information about the backend with the specified
2631 process ID, or one record for each active backend in the system if NULL
2632 is specified. The fields returned are a subset of those in the
2633 pg_stat_activity view.
2635 pg_stat_get_backend_wal ( integer ) → record
2637 Returns WAL statistics about the backend with the specified process ID.
2638 The output fields are exactly the same as the ones in the pg_stat_wal
2641 The function does not return WAL statistics for the checkpointer, the
2642 background writer, the startup process and the autovacuum launcher.
2644 pg_stat_get_snapshot_timestamp () → timestamp with time zone
2646 Returns the timestamp of the current statistics snapshot, or NULL if no
2647 statistics snapshot has been taken. A snapshot is taken the first time
2648 cumulative statistics are accessed in a transaction if
2649 stats_fetch_consistency is set to snapshot
2651 pg_stat_get_xact_blocks_fetched ( oid ) → bigint
2653 Returns the number of block read requests for table or index, in the
2654 current transaction. This number minus pg_stat_get_xact_blocks_hit
2655 gives the number of kernel read() calls; the number of actual physical
2656 reads is usually lower due to kernel-level buffering.
2658 pg_stat_get_xact_blocks_hit ( oid ) → bigint
2660 Returns the number of block read requests for table or index, in the
2661 current transaction, found in cache (not triggering kernel read()
2664 pg_stat_clear_snapshot () → void
2666 Discards the current statistics snapshot or cached information.
2668 pg_stat_reset () → void
2670 Resets all statistics counters for the current database to zero.
2672 This function is restricted to superusers by default, but other users
2673 can be granted EXECUTE to run the function.
2675 pg_stat_reset_shared ( [ target text DEFAULT NULL ] ) → void
2677 Resets some cluster-wide statistics counters to zero, depending on the
2678 argument. target can be:
2679 * archiver: Reset all the counters shown in the pg_stat_archiver
2681 * bgwriter: Reset all the counters shown in the pg_stat_bgwriter
2683 * checkpointer: Reset all the counters shown in the
2684 pg_stat_checkpointer view.
2685 * io: Reset all the counters shown in the pg_stat_io view.
2686 * recovery_prefetch: Reset all the counters shown in the
2687 pg_stat_recovery_prefetch view.
2688 * slru: Reset all the counters shown in the pg_stat_slru view.
2689 * wal: Reset all the counters shown in the pg_stat_wal view.
2690 * NULL or not specified: All the counters from the views listed above
2693 This function is restricted to superusers by default, but other users
2694 can be granted EXECUTE to run the function.
2696 pg_stat_reset_single_table_counters ( oid ) → void
2698 Resets statistics for a single table or index in the current database
2699 or shared across all databases in the cluster to zero.
2701 This function is restricted to superusers by default, but other users
2702 can be granted EXECUTE to run the function.
2704 pg_stat_reset_backend_stats ( integer ) → void
2706 Resets statistics for a single backend with the specified process ID to
2709 This function is restricted to superusers by default, but other users
2710 can be granted EXECUTE to run the function.
2712 pg_stat_reset_single_function_counters ( oid ) → void
2714 Resets statistics for a single function in the current database to
2717 This function is restricted to superusers by default, but other users
2718 can be granted EXECUTE to run the function.
2720 pg_stat_reset_slru ( [ target text DEFAULT NULL ] ) → void
2722 Resets statistics to zero for a single SLRU cache, or for all SLRUs in
2723 the cluster. If target is NULL or is not specified, all the counters
2724 shown in the pg_stat_slru view for all SLRU caches are reset. The
2725 argument can be one of commit_timestamp, multixact_member,
2726 multixact_offset, notify, serializable, subtransaction, or transaction
2727 to reset the counters for only that entry. If the argument is other (or
2728 indeed, any unrecognized name), then the counters for all other SLRU
2729 caches, such as extension-defined caches, are reset.
2731 This function is restricted to superusers by default, but other users
2732 can be granted EXECUTE to run the function.
2734 pg_stat_reset_replication_slot ( text ) → void
2736 Resets statistics of the replication slot defined by the argument. If
2737 the argument is NULL, resets statistics for all the replication slots.
2739 This function is restricted to superusers by default, but other users
2740 can be granted EXECUTE to run the function.
2742 pg_stat_reset_subscription_stats ( oid ) → void
2744 Resets statistics for a single subscription shown in the
2745 pg_stat_subscription_stats view to zero. If the argument is NULL, reset
2746 statistics for all subscriptions.
2748 This function is restricted to superusers by default, but other users
2749 can be granted EXECUTE to run the function.
2753 Using pg_stat_reset() also resets counters that autovacuum uses to
2754 determine when to trigger a vacuum or an analyze. Resetting these
2755 counters can cause autovacuum to not perform necessary work, which can
2756 cause problems such as table bloat or out-dated table statistics. A
2757 database-wide ANALYZE is recommended after the statistics have been
2760 pg_stat_get_activity, the underlying function of the pg_stat_activity
2761 view, returns a set of records containing all the available information
2762 about each backend process. Sometimes it may be more convenient to
2763 obtain just a subset of this information. In such cases, another set of
2764 per-backend statistics access functions can be used; these are shown in
2765 Table 27.37. These access functions use the session's backend ID
2766 number, which is a small integer (>= 0) that is distinct from the
2767 backend ID of any concurrent session, although a session's ID can be
2768 recycled as soon as it exits. The backend ID is used, among other
2769 things, to identify the session's temporary schema if it has one. The
2770 function pg_stat_get_backend_idset provides a convenient way to list
2771 all the active backends' ID numbers for invoking these functions. For
2772 example, to show the PIDs and current queries of all backends:
2773 SELECT pg_stat_get_backend_pid(backendid) AS pid,
2774 pg_stat_get_backend_activity(backendid) AS query
2775 FROM pg_stat_get_backend_idset() AS backendid;
2777 Table 27.37. Per-Backend Statistics Functions
2783 pg_stat_get_backend_activity ( integer ) → text
2785 Returns the text of this backend's most recent query.
2787 pg_stat_get_backend_activity_start ( integer ) → timestamp with time
2790 Returns the time when the backend's most recent query was started.
2792 pg_stat_get_backend_client_addr ( integer ) → inet
2794 Returns the IP address of the client connected to this backend.
2796 pg_stat_get_backend_client_port ( integer ) → integer
2798 Returns the TCP port number that the client is using for communication.
2800 pg_stat_get_backend_dbid ( integer ) → oid
2802 Returns the OID of the database this backend is connected to.
2804 pg_stat_get_backend_idset () → setof integer
2806 Returns the set of currently active backend ID numbers.
2808 pg_stat_get_backend_pid ( integer ) → integer
2810 Returns the process ID of this backend.
2812 pg_stat_get_backend_start ( integer ) → timestamp with time zone
2814 Returns the time when this process was started.
2816 pg_stat_get_backend_subxact ( integer ) → record
2818 Returns a record of information about the subtransactions of the
2819 backend with the specified ID. The fields returned are subxact_count,
2820 which is the number of subtransactions in the backend's subtransaction
2821 cache, and subxact_overflow, which indicates whether the backend's
2822 subtransaction cache is overflowed or not.
2824 pg_stat_get_backend_userid ( integer ) → oid
2826 Returns the OID of the user logged into this backend.
2828 pg_stat_get_backend_wait_event ( integer ) → text
2830 Returns the wait event name if this backend is currently waiting,
2831 otherwise NULL. See Table 27.5 through Table 27.13.
2833 pg_stat_get_backend_wait_event_type ( integer ) → text
2835 Returns the wait event type name if this backend is currently waiting,
2836 otherwise NULL. See Table 27.4 for details.
2838 pg_stat_get_backend_xact_start ( integer ) → timestamp with time zone
2840 Returns the time when the backend's current transaction was started.