27.2. 통계 수집기

27.2.1. 통계 수집기 환경설정
27.2.2. 통계 정보 보기
27.2.3. pg_stat_activity
27.2.4. pg_stat_replication
27.2.5. pg_stat_wal_receiver
27.2.6. pg_stat_subscription
27.2.7. pg_stat_ssl
27.2.8. pg_stat_gssapi
27.2.9. pg_stat_archiver
27.2.10. pg_stat_bgwriter
27.2.11. pg_stat_database
27.2.12. pg_stat_database_conflicts
27.2.13. pg_stat_all_tables
27.2.14. pg_stat_all_indexes
27.2.15. pg_statio_all_tables
27.2.16. pg_statio_all_indexes
27.2.17. pg_statio_all_sequences
27.2.18. pg_stat_user_functions
27.2.19. pg_stat_slru
27.2.20. Statistics Functions

PostgreSQL 통계 수집기 statistics collector는 서버 운영 상태에 대한 정보를 수집하거나 보고하기 위한 작업을 하는 백그라운드 시스템이다. 현재, 이 수집기는 테이블이나 인덱스의 디스크 블록 단위 또는 개별 로우 단위의 접근 회수를 수집할 수 있다. 또한 각 테이블에 저장 되어있는 총 로우 수를 수집하며, 각 테이블에 대한 vacuum 작업과, analyze 작업에 관한 정보들도 수집한다. 또한 사용자 정의 함수들의 호출 회수와, 그것들의 각각 총 수행 시간들도 수집한다.

또한 PostgreSQL에서는 현재 시스템에서 어떻게 운영 되고 있는지에 대한 동적 정보를 제공한다. 예를 들어 다른 서버 프로세스가 현재 어떤 작업을 하고 있는지, 어떤 클라이언트들이 접속해 있는지를 알 수 있다. 이 기능은 수집기 프로세스와 별개로 제공하고 있는 기능이다.

27.2.1. 통계 수집기 환경설정

통계 자료를 수집한다는 것은 궁극적으로는 그 만큼의 추가 비용을 서버가 사용한다는 것을 의미한다. 그래서, 그 추가 비용을 얼마만큼 쓸 것인지에 대한 결정을 서버 환경변수로 제어할 수 있다. 다음은 postgresql.conf 환경설정 파일에서 사용할 수 있는 환경변수들이다. (이들에 대한 보다 자세한 부분은 19장을 참고하라.)

track_activities 설정값을 활성화하면 각각의 서버 프로세스들은 현재 자신이 하고 있는 작업을 프로세스 이름으로 보여준다.

track_counts 설정값을 활성화하면 테이블과 인덱스의 사용빈도를 통계 수집기가 수집한다.

track_functions 설정값을 활성화하면 사용자 정의 함수들의 사용빈도를 통계 수집기가 수집한다.

track_io_timing 설정값을 활성화면 블록 읽기 쓰기 회수를 통계 수집기가 수집한다.

일반적으로 이 환경설정 변수들은 postgresql.conf에서 그 값을 지정하면, 이것은 모든 서버의 프로세스들을 대상으로 작동하게 된다. 하지만, SET 명령을 이용해서, 개별 세션 단위로 이 설정값을 변경할 수도 있다. (이 작업은 일반 사용자가 악의적으로 사용될 가능성이 있기 때문에, 슈퍼유저만 사용할 수 있다.)

통계 수집기가 만든 정보는 stats_temp_directory 설정값으로 지정한 디렉터리 (초기값은 pg_stat_tmp) 안에 있는 임시파일로 저장되고, 그것을 여러 다른 PostgreSQL 프로세스들이 이용한다. 보다 나은 성능을 위해서는 이 파일의 I/O 성능을 높이기 위해 이 디렉터리를 메모리 기반 파일시스템에 두는 것도 좋은 방법이다. 이 통계 정보는 서버가 중지 될 때 pg_stat 디렉터리 쪽으로 복사하는 작업을 하기 때문에, 서버 중지, 재시작에도 자료를 그대로 유지할 수 있다.

27.2.2. 통계 정보 보기

위에서 설명한 시스템의 현재 상태는 표 27.1 뷰들을 통해서 살펴볼 수 있고, 그 외 수집된 통계 정보는 아래 표 27.2에서 나열한 여러 뷰를 통해서 살펴 볼 수 있다. 다른 방법으로는 27.2.20절에서 제공하는 여러 통계 정보 보기 함수들을 이용해서 필요한 뷰를 직접 만들어서 살펴 볼 수도 있을 것이다.

여기서 중요한 점은 살펴 보고 있는 수집된 통계 정보는 현재 데이터베이스의 정확한 현재 상태가 아니라는 점이다. 각 개별 프로세스들이 수집한 통계 정보는 그 프로세스가 아무런 작업을 하고 있지 않을 때, 수집기에게 전달한다. 즉 한 쿼리가 실행 되고 있다거나 트랜잭션 내에 있다면, 그 과정에 생긴 통계 정보들은 반영되지 않고 있다는 것이다. 또한 통계 수집기의 작업은 PGSTAT_STAT_INTERVAL (기본값은 500ms 이다) 시간 간격으로 진행된다. 즉 이 만큼의 통계 정보 오차가 발생한다. 하지만, track_activities 관련 정보는 항상 즉시 반영 된다.

또 다른 중요한 점은 한 통계 정보는 해당 뷰나, 함수로 출력할 때, 한 트랜잭션 내에서는 항상 같은 값을 출력한다. 즉, 트랜젹션이 끝날 때까지 그 값을 유지한다. 이와 비슷하게 모든 세션들의 현재 쿼리에 대한 정보도 하나의 트랜잭션 내에서는 같은 정보를 출력한다. 이것은 버그가 아니라 특성이다. 이것은 한 트랜잭션 내에서 그 통계 정보가 일정하게 유지 되도록해서 여러 다른 쿼리들에서 그 값을 일관성 있게 한다. 하지만 이것을 원치 않는다면 각 쿼리들을 트랜잭션 단위로 분리해서 작업하면 된다. 다른 방법으로 pg_stat_clear_snapshot() 함수를 사용해서, 현재 스냅숏으로 지정된 통계 정보를 버리고 새 통계 정보를 사용할 수도 있다.

하나의 트랜잭션 내에서 그 자신의 통계 정보 (아직까지 수집기 쪽으로 보내지 않은 현재 작업 내역에 대한 정보)들은 다음과 같은 뷰에서 제공한다: pg_stat_xact_all_tables, pg_stat_xact_sys_tables, pg_stat_xact_user_tables, pg_stat_xact_user_functions. 이들의 통계 정보는 현재 트랜잭션 내에서도 자신의 세션 작업에 대한 통계치를 반영 해서 다른 세션에서 수집된 정보와 자신의 세션에서 수집된 정보와 차이가 생길 수도 있다.

Some of the information in the dynamic statistics views shown in 표 27.1 is security restricted. Ordinary users can only see all the information about their own sessions (sessions belonging to a role that they are a member of). In rows about other sessions, many columns will be null. Note, however, that the existence of a session and its general properties such as its sessions user and database are visible to all users. Superusers and members of the built-in role pg_read_all_stats (see also 21.5절) can see all the information about all sessions.

표 27.1. 동적 통계 정보 뷰들

뷰 이름설명
pg_stat_activity 세션 프로세스들의 정보를 각각 하나의 로우로 보여준다. 이 프로세스들은 현재 서버를 사용하고는 있는 - 클라이언트가 서버로 접속 해서 만들어진 하위 서버 프로세스들이며, 이들의 현재 상태, 실행 중인 쿼리들을 살펴 볼 수 있다. 자세한 내용은 pg_stat_activity 참조.
pg_stat_replication 하나의 WAL 송신 프로세스에 대해서 하나의 로우로, 대기 서버 쪽으로 보내는 리플리케이션 작업에 대한 통계 정보를 보여준다. 자세한 내용은 pg_stat_replication 참조.
pg_stat_wal_receiverOnly one row, showing statistics about the WAL receiver from that receiver's connected server. See pg_stat_wal_receiver for details.
pg_stat_subscriptionAt least one row per subscription, showing information about the subscription workers. See pg_stat_subscription for details.
pg_stat_sslOne row per connection (regular and replication), showing information about SSL used on this connection. See pg_stat_ssl for details.
pg_stat_gssapiOne row per connection (regular and replication), showing information about GSSAPI authentication and encryption used on this connection. See pg_stat_gssapi for details.
pg_stat_progress_analyzeOne row for each backend (including autovacuum worker processes) running ANALYZE, showing current progress. See 27.4.1절.
pg_stat_progress_create_indexOne row for each backend running CREATE INDEX or REINDEX, showing current progress. See 27.4.2절.
pg_stat_progress_vacuumOne row for each backend (including autovacuum worker processes) running VACUUM, showing current progress. See 27.4.3절.
pg_stat_progress_clusterOne row for each backend running CLUSTER or VACUUM FULL, showing current progress. See 27.4.4절.
pg_stat_progress_basebackupOne row for each WAL sender process streaming a base backup, showing current progress. See 27.4.5절.

표 27.2. 수집된 통계 정보 뷰들

뷰 이름설명
pg_stat_archiverWAL 아카이버 프로세스 작동에 대한 통계 정보를 하나의 로우로 보여준다. 자세한 사항은 pg_stat_archiver 참조.
pg_stat_bgwriter 백그라운드 라이터 프로세스의 작업 통계 정보. 자세한 내용은 pg_stat_bgwriter 참조.
pg_stat_database한 로우에 하나씩 각 데이터베이스 전역 통계 정보를 보여 준다. 자세한 내용은 pg_stat_database 참조.
pg_stat_database_conflicts 하나의 데이터베이스에서 그 전역에 걸쳐 발생한 대기 서버 복제 작업 충돌에 의한 쿼리 실행 실패 통계 정보를 각각 하나의 로우로 보여준다. 자세한 내용은 pg_stat_database_conflicts 참조.
pg_stat_all_tables 현재 접속한 데이터베이스에 속한 모든 테이블에 대해서 한 로우씩 그 테이블 사용에 대한 통계 정보를 보여 준다. 자세한 내용은 pg_stat_all_tables 참조.
pg_stat_sys_tablespg_stat_all_tables 내용과 같은데, 시스템 테이블에 대해서만 보여준다.
pg_stat_user_tablespg_stat_all_tables 내용과 같은데, 시스템 테이블을 제외한 현재 사용자 접근 할 수 있는 테이블에 대한 정보만 보여준다.
pg_stat_xact_all_tablespg_stat_all_tables 내용과 비슷하지만, 여기서 반영된 숫자들은 현재 트랜잭션 내에서 반영된 정보만 보여준다. (즉 pg_stat_all_tables 쪽으로 반영 되지 않은 트랜잭션 내의 정보다). 이 뷰에는 사용하는 실 로우 수, 사용하지 않는 로우(dead row) 수, vacuum과 analyze 작업에 관계된 정보는 제공하지 않는다.
pg_stat_xact_sys_tablespg_stat_xact_all_tables 내용과 같은데, 시스템 테이블에 대해서만 보여준다.
pg_stat_xact_user_tablespg_stat_xact_all_tables 내용과 같은데, 시스템 테이블을 제외한 현재 사용자가 접근 할 수 있는 테이블에 대해서만 보여준다.
pg_stat_all_indexes 현재 접속한 데이터베이스에 속한 모든 인덱스에 대해서 한 로우씩 그 인덱스 사용에 대한 통계 정보를 보여 준다. 자세한 내용은 pg_stat_all_indexes 참조.
pg_stat_sys_indexespg_stat_all_indexes 내용과 같은데, 시스템 인덱스에 대해서만 보여준다.
pg_stat_user_indexespg_stat_all_indexes 내용과 같은데, 시스템 인덱스를 제외한 현재 사용자가 접근 할 수 있는 인덱스에 대해서만 보여준다.
pg_statio_all_tables 현재 접속한 데이터베이스에 속한 모든 테이블에 대해서 한 로우씩 그 테이블에 대한 I/O 통계 정보를 보여 준다. 자세한 내용은 pg_statio_all_tables 참조.
pg_statio_sys_tablespg_statio_all_tables 내용과 같은데, 시스템 테이블에 대해서만 보여준다.
pg_statio_user_tablespg_statio_all_tables 내용과 같은데, 시스템 테이블을 제외한 현재 사용자가 접근 할 수 있는 테이블에 대해서만 보여준다.
pg_statio_all_indexes 현재 접속한 데이터베이스에 속한 모든 인덱스에 대해서 한 로우씩 그 인덱스에 대한 I/O 통계 정보를 보여 준다. 자세한 내용은 pg_statio_all_indexes 참조.
pg_statio_sys_indexespg_statio_all_indexes 내용과 같은데, 시스템 인덱스에 대해서만 보여준다.
pg_statio_user_indexespg_statio_all_indexes 내용과 같은데, 시스템 인덱스를 제외한 현재 사용자가 접근 할 수 있는 인덱스에 대해서만 보여준다.
pg_statio_all_sequences 현재 접속한 데이터베이스에 속한 모든 시퀀스에 대해서 한 로우씩 그 시퀀스에 대한 I/O 통계 정보를 보여 준다. 자세한 내용은 pg_statio_all_sequences참조.
pg_statio_sys_sequencespg_statio_all_sequences 내용과 같은데, 시스템 시퀀스에 대해서만 보여준다. (현재 사용하고 있는 시스템 시퀀스가 없음으로 이 뷰는 항상 그 내용이 비어있을 것이다.)
pg_statio_user_sequencespg_statio_all_sequences 내용과 같은데, 시스템 시퀀스를 제외한 현재 사용자가 접근 할 수 있는 시퀀스에 대해서만 보여준다.
pg_stat_user_functions 현재 데이터베이스에 만들어진 사용자 정의 함수들의 실행에 대한 통계 정보를 보여준다. 자세한 내용은 pg_stat_user_functions 참조.
pg_stat_xact_user_functionspg_stat_user_functions 내용과 비슷하지만, 여기서 반영된 숫자들은 현재 트랜잭션 내에서 반영된 정보만 보여준다, (즉 pg_stat_user_functions 쪽으로 반영 되지 않은 트랜잭션 내의 정보다).
pg_stat_slruOne row per SLRU, showing statistics of operations. See pg_stat_slru for details.

인덱스 별 통계 정보는 어느 인덱스가 많이 사용되며, 어떻게 영향을 미치는 지를 조사하는데 특히 유용하게 쓰인다.

pg_statio_ 뷰들은 공유 버퍼의 사용 빈도를 파악하는데 가장 기본이 되는 것들이다. 이상적인 서버 운영 모습은 디스크 읽기 빈도 보다 공유 버퍼를 사용하는(buffer hit) 빈도가 훨씬 높아서, 대부분의 작업이 커널 호출 작업 없이 이루워 지도록 하는 것이다. 한편, PostgreSQL 에서는 단지 이 서버 기준으로 디스크를 읽은 것과 서버의 공유 버퍼를 사용한 것에 대한 정보만 제공 할 뿐이다. 즉, 커널의 I/O 캐시 사용 빈도에 대해서는 제공하지 않는다. 다시 말하면, 정말 디스크를 읽은 것인지, OS의 I/O 캐시를 사용한 것인지는 이 뷰를 통해서는 알 수 없다. 이런 세세한 부분까지 살펴 보려면, OS 관련 도구들을 이용해야 할 것이다.

아래 부분부터는 모바일 호환성 작업으로 문서 구조가 너무 많이 바뀌어 기존 한글 문서와 통합이 거의 불가능했다. 틈틈이 옮기겠다 - 옮긴이

27.2.3. pg_stat_activity

The pg_stat_activity view will have one row per server process, showing information related to the current activity of that process.

표 27.3. pg_stat_activity View

Column Type

Description

datid oid

OID of the database this backend is connected to

datname name

Name of the database this backend is connected to

pid integer

Process ID of this backend

leader_pid integer

Process ID of the parallel group leader, if this process is a parallel query worker. NULL if this process is a parallel group leader or does not participate in parallel query.

usesysid oid

OID of the user logged into this backend

usename name

Name of the user logged into this backend

application_name text

Name of the application that is connected to this backend

client_addr inet

IP address of the client connected to this backend. If this field is null, it indicates either that the client is connected via a Unix socket on the server machine or that this is an internal process such as autovacuum.

client_hostname text

Host name of the connected client, as reported by a reverse DNS lookup of client_addr. This field will only be non-null for IP connections, and only when log_hostname is enabled.

client_port integer

TCP port number that the client is using for communication with this backend, or -1 if a Unix socket is used. If this field is null, it indicates that this is an internal server process.

backend_start timestamp with time zone

Time when this process was started. For client backends, this is the time the client connected to the server.

xact_start timestamp with time zone

Time when this process' current transaction was started, or null if no transaction is active. If the current query is the first of its transaction, this column is equal to the query_start column.

query_start timestamp with time zone

Time when the currently active query was started, or if state is not active, when the last query was started

state_change timestamp with time zone

Time when the state was last changed

wait_event_type text

The type of event for which the backend is waiting, if any; otherwise NULL. See 표 27.4.

wait_event text

Wait event name if backend is currently waiting, otherwise NULL. See 표 27.5 through 표 27.13.

state text

Current overall state of this backend. Possible values are:

  • active: The backend is executing a query.

  • idle: The backend is waiting for a new client command.

  • idle in transaction: The backend is in a transaction, but is not currently executing a query.

  • idle in transaction (aborted): This state is similar to idle in transaction, except one of the statements in the transaction caused an error.

  • fastpath function call: The backend is executing a fast-path function.

  • disabled: This state is reported if track_activities is disabled in this backend.

backend_xid xid

Top-level transaction identifier of this backend, if any.

backend_xmin xid

The current backend's xmin horizon.

query text

Text of this backend's most recent query. If state is active this field shows the currently executing query. In all other states, it shows the last query that was executed. By default the query text is truncated at 1024 bytes; this value can be changed via the parameter track_activity_query_size.

backend_type text

Type of current backend. Possible types are autovacuum launcher, autovacuum worker, logical replication launcher, logical replication worker, parallel worker, background writer, client backend, checkpointer, startup, walreceiver, walsender and walwriter. In addition, background workers registered by extensions may have additional types.


참고

The wait_event and state columns are independent. If a backend is in the active state, it may or may not be waiting on some event. If the state is active and wait_event is non-null, it means that a query is being executed, but is being blocked somewhere in the system.

표 27.4. Wait Event Types

Wait Event TypeDescription
ActivityThe server process is idle. This event type indicates a process waiting for activity in its main processing loop. wait_event will identify the specific wait point; see 표 27.5.
BufferPinThe server process is waiting for exclusive access to a data buffer. Buffer pin waits can be protracted if another process holds an open cursor that last read data from the buffer in question. See 표 27.6.
ClientThe server process is waiting for activity on a socket connected to a user application. Thus, the server expects something to happen that is independent of its internal processes. wait_event will identify the specific wait point; see 표 27.7.
ExtensionThe server process is waiting for some condition defined by an extension module. See 표 27.8.
IOThe server process is waiting for an I/O operation to complete. wait_event will identify the specific wait point; see 표 27.9.
IPCThe server process is waiting for some interaction with another server process. wait_event will identify the specific wait point; see 표 27.10.
LockThe server process is waiting for a heavyweight lock. Heavyweight locks, also known as lock manager locks or simply locks, primarily protect SQL-visible objects such as tables. However, they are also used to ensure mutual exclusion for certain internal operations such as relation extension. wait_event will identify the type of lock awaited; see 표 27.11.
LWLock The server process is waiting for a lightweight lock. Most such locks protect a particular data structure in shared memory. wait_event will contain a name identifying the purpose of the lightweight lock. (Some locks have specific names; others are part of a group of locks each with a similar purpose.) See 표 27.12.
TimeoutThe server process is waiting for a timeout to expire. wait_event will identify the specific wait point; see 표 27.13.

표 27.5. Wait Events of Type Activity

Activity Wait EventDescription
ArchiverMainWaiting in main loop of archiver process.
AutoVacuumMainWaiting in main loop of autovacuum launcher process.
BgWriterHibernateWaiting in background writer process, hibernating.
BgWriterMainWaiting in main loop of background writer process.
CheckpointerMainWaiting in main loop of checkpointer process.
LogicalApplyMainWaiting in main loop of logical replication apply process.
LogicalLauncherMainWaiting in main loop of logical replication launcher process.
PgStatMainWaiting in main loop of statistics collector process.
RecoveryWalStreamWaiting in main loop of startup process for WAL to arrive, during streaming recovery.
SysLoggerMainWaiting in main loop of syslogger process.
WalReceiverMainWaiting in main loop of WAL receiver process.
WalSenderMainWaiting in main loop of WAL sender process.
WalWriterMainWaiting in main loop of WAL writer process.

표 27.6. Wait Events of Type BufferPin

BufferPin Wait EventDescription
BufferPinWaiting to acquire an exclusive pin on a buffer.

표 27.7. Wait Events of Type Client

Client Wait EventDescription
ClientReadWaiting to read data from the client.
ClientWriteWaiting to write data to the client.
GSSOpenServerWaiting to read data from the client while establishing a GSSAPI session.
LibPQWalReceiverConnectWaiting in WAL receiver to establish connection to remote server.
LibPQWalReceiverReceiveWaiting in WAL receiver to receive data from remote server.
SSLOpenServerWaiting for SSL while attempting connection.
WalReceiverWaitStartWaiting for startup process to send initial data for streaming replication.
WalSenderWaitForWALWaiting for WAL to be flushed in WAL sender process.
WalSenderWriteDataWaiting for any activity when processing replies from WAL receiver in WAL sender process.

표 27.8. Wait Events of Type Extension

Extension Wait EventDescription
ExtensionWaiting in an extension.

표 27.9. Wait Events of Type IO

IO Wait EventDescription
BufFileReadWaiting for a read from a buffered file.
BufFileWriteWaiting for a write to a buffered file.
ControlFileReadWaiting for a read from the pg_control file.
ControlFileSyncWaiting for the pg_control file to reach durable storage.
ControlFileSyncUpdateWaiting for an update to the pg_control file to reach durable storage.
ControlFileWriteWaiting for a write to the pg_control file.
ControlFileWriteUpdateWaiting for a write to update the pg_control file.
CopyFileReadWaiting for a read during a file copy operation.
CopyFileWriteWaiting for a write during a file copy operation.
DSMFillZeroWriteWaiting to fill a dynamic shared memory backing file with zeroes.
DataFileExtendWaiting for a relation data file to be extended.
DataFileFlushWaiting for a relation data file to reach durable storage.
DataFileImmediateSyncWaiting for an immediate synchronization of a relation data file to durable storage.
DataFilePrefetchWaiting for an asynchronous prefetch from a relation data file.
DataFileReadWaiting for a read from a relation data file.
DataFileSyncWaiting for changes to a relation data file to reach durable storage.
DataFileTruncateWaiting for a relation data file to be truncated.
DataFileWriteWaiting for a write to a relation data file.
LockFileAddToDataDirReadWaiting for a read while adding a line to the data directory lock file.
LockFileAddToDataDirSyncWaiting for data to reach durable storage while adding a line to the data directory lock file.
LockFileAddToDataDirWriteWaiting for a write while adding a line to the data directory lock file.
LockFileCreateReadWaiting to read while creating the data directory lock file.
LockFileCreateSyncWaiting for data to reach durable storage while creating the data directory lock file.
LockFileCreateWriteWaiting for a write while creating the data directory lock file.
LockFileReCheckDataDirReadWaiting for a read during recheck of the data directory lock file.
LogicalRewriteCheckpointSyncWaiting for logical rewrite mappings to reach durable storage during a checkpoint.
LogicalRewriteMappingSyncWaiting for mapping data to reach durable storage during a logical rewrite.
LogicalRewriteMappingWriteWaiting for a write of mapping data during a logical rewrite.
LogicalRewriteSyncWaiting for logical rewrite mappings to reach durable storage.
LogicalRewriteTruncateWaiting for truncate of mapping data during a logical rewrite.
LogicalRewriteWriteWaiting for a write of logical rewrite mappings.
RelationMapReadWaiting for a read of the relation map file.
RelationMapSyncWaiting for the relation map file to reach durable storage.
RelationMapWriteWaiting for a write to the relation map file.
ReorderBufferReadWaiting for a read during reorder buffer management.
ReorderBufferWriteWaiting for a write during reorder buffer management.
ReorderLogicalMappingReadWaiting for a read of a logical mapping during reorder buffer management.
ReplicationSlotReadWaiting for a read from a replication slot control file.
ReplicationSlotRestoreSyncWaiting for a replication slot control file to reach durable storage while restoring it to memory.
ReplicationSlotSyncWaiting for a replication slot control file to reach durable storage.
ReplicationSlotWriteWaiting for a write to a replication slot control file.
SLRUFlushSyncWaiting for SLRU data to reach durable storage during a checkpoint or database shutdown.
SLRUReadWaiting for a read of an SLRU page.
SLRUSyncWaiting for SLRU data to reach durable storage following a page write.
SLRUWriteWaiting for a write of an SLRU page.
SnapbuildReadWaiting for a read of a serialized historical catalog snapshot.
SnapbuildSyncWaiting for a serialized historical catalog snapshot to reach durable storage.
SnapbuildWriteWaiting for a write of a serialized historical catalog snapshot.
TimelineHistoryFileSyncWaiting for a timeline history file received via streaming replication to reach durable storage.
TimelineHistoryFileWriteWaiting for a write of a timeline history file received via streaming replication.
TimelineHistoryReadWaiting for a read of a timeline history file.
TimelineHistorySyncWaiting for a newly created timeline history file to reach durable storage.
TimelineHistoryWriteWaiting for a write of a newly created timeline history file.
TwophaseFileReadWaiting for a read of a two phase state file.
TwophaseFileSyncWaiting for a two phase state file to reach durable storage.
TwophaseFileWriteWaiting for a write of a two phase state file.
WALBootstrapSyncWaiting for WAL to reach durable storage during bootstrapping.
WALBootstrapWriteWaiting for a write of a WAL page during bootstrapping.
WALCopyReadWaiting for a read when creating a new WAL segment by copying an existing one.
WALCopySyncWaiting for a new WAL segment created by copying an existing one to reach durable storage.
WALCopyWriteWaiting for a write when creating a new WAL segment by copying an existing one.
WALInitSyncWaiting for a newly initialized WAL file to reach durable storage.
WALInitWriteWaiting for a write while initializing a new WAL file.
WALReadWaiting for a read from a WAL file.
WALSenderTimelineHistoryReadWaiting for a read from a timeline history file during a walsender timeline command.
WALSyncWaiting for a WAL file to reach durable storage.
WALSyncMethodAssignWaiting for data to reach durable storage while assigning a new WAL sync method.
WALWriteWaiting for a write to a WAL file.

표 27.10. Wait Events of Type IPC

IPC Wait EventDescription
BackupWaitWalArchiveWaiting for WAL files required for a backup to be successfully archived.
BgWorkerShutdownWaiting for background worker to shut down.
BgWorkerStartupWaiting for background worker to start up.
BtreePageWaiting for the page number needed to continue a parallel B-tree scan to become available.
CheckpointDoneWaiting for a checkpoint to complete.
CheckpointStartWaiting for a checkpoint to start.
ExecuteGatherWaiting for activity from a child process while executing a Gather plan node.
HashBatchAllocateWaiting for an elected Parallel Hash participant to allocate a hash table.
HashBatchElectWaiting to elect a Parallel Hash participant to allocate a hash table.
HashBatchLoadWaiting for other Parallel Hash participants to finish loading a hash table.
HashBuildAllocateWaiting for an elected Parallel Hash participant to allocate the initial hash table.
HashBuildElectWaiting to elect a Parallel Hash participant to allocate the initial hash table.
HashBuildHashInnerWaiting for other Parallel Hash participants to finish hashing the inner relation.
HashBuildHashOuterWaiting for other Parallel Hash participants to finish partitioning the outer relation.
HashGrowBatchesAllocateWaiting for an elected Parallel Hash participant to allocate more batches.
HashGrowBatchesDecideWaiting to elect a Parallel Hash participant to decide on future batch growth.
HashGrowBatchesElectWaiting to elect a Parallel Hash participant to allocate more batches.
HashGrowBatchesFinishWaiting for an elected Parallel Hash participant to decide on future batch growth.
HashGrowBatchesRepartitionWaiting for other Parallel Hash participants to finish repartitioning.
HashGrowBucketsAllocateWaiting for an elected Parallel Hash participant to finish allocating more buckets.
HashGrowBucketsElectWaiting to elect a Parallel Hash participant to allocate more buckets.
HashGrowBucketsReinsertWaiting for other Parallel Hash participants to finish inserting tuples into new buckets.
LogicalSyncDataWaiting for a logical replication remote server to send data for initial table synchronization.
LogicalSyncStateChangeWaiting for a logical replication remote server to change state.
MessageQueueInternalWaiting for another process to be attached to a shared message queue.
MessageQueuePutMessageWaiting to write a protocol message to a shared message queue.
MessageQueueReceiveWaiting to receive bytes from a shared message queue.
MessageQueueSendWaiting to send bytes to a shared message queue.
ParallelBitmapScanWaiting for parallel bitmap scan to become initialized.
ParallelCreateIndexScanWaiting for parallel CREATE INDEX workers to finish heap scan.
ParallelFinishWaiting for parallel workers to finish computing.
ProcArrayGroupUpdateWaiting for the group leader to clear the transaction ID at end of a parallel operation.
ProcSignalBarrierWaiting for a barrier event to be processed by all backends.
PromoteWaiting for standby promotion.
RecoveryConflictSnapshotWaiting for recovery conflict resolution for a vacuum cleanup.
RecoveryConflictTablespaceWaiting for recovery conflict resolution for dropping a tablespace.
RecoveryPauseWaiting for recovery to be resumed.
ReplicationOriginDropWaiting for a replication origin to become inactive so it can be dropped.
ReplicationSlotDropWaiting for a replication slot to become inactive so it can be dropped.
SafeSnapshotWaiting to obtain a valid snapshot for a READ ONLY DEFERRABLE transaction.
SyncRepWaiting for confirmation from a remote server during synchronous replication.
XactGroupUpdateWaiting for the group leader to update transaction status at end of a parallel operation.

표 27.11. Wait Events of Type Lock

Lock Wait EventDescription
advisoryWaiting to acquire an advisory user lock.
extendWaiting to extend a relation.
frozenidWaiting to update pg_database.datfrozenxid and pg_database.datminmxid.
objectWaiting to acquire a lock on a non-relation database object.
pageWaiting to acquire a lock on a page of a relation.
relationWaiting to acquire a lock on a relation.
spectokenWaiting to acquire a speculative insertion lock.
transactionidWaiting for a transaction to finish.
tupleWaiting to acquire a lock on a tuple.
userlockWaiting to acquire a user lock.
virtualxidWaiting to acquire a virtual transaction ID lock.

표 27.12. Wait Events of Type LWLock

LWLock Wait EventDescription
AddinShmemInitWaiting to manage an extension's space allocation in shared memory.
AutoFileWaiting to update the postgresql.auto.conf file.
AutovacuumWaiting to read or update the current state of autovacuum workers.
AutovacuumScheduleWaiting to ensure that a table selected for autovacuum still needs vacuuming.
BackgroundWorkerWaiting to read or update background worker state.
BtreeVacuumWaiting to read or update vacuum-related information for a B-tree index.
BufferContentWaiting to access a data page in memory.
BufferIOWaiting for I/O on a data page.
BufferMappingWaiting to associate a data block with a buffer in the buffer pool.
CheckpointWaiting to begin a checkpoint.
CheckpointerCommWaiting to manage fsync requests.
CommitTsWaiting to read or update the last value set for a transaction commit timestamp.
CommitTsBufferWaiting for I/O on a commit timestamp SLRU buffer.
CommitTsSLRUWaiting to access the commit timestamp SLRU cache.
ControlFileWaiting to read or update the pg_control file or create a new WAL file.
DynamicSharedMemoryControlWaiting to read or update dynamic shared memory allocation information.
LockFastPathWaiting to read or update a process' fast-path lock information.
LockManagerWaiting to read or update information about heavyweight locks.
LogicalRepWorkerWaiting to read or update the state of logical replication workers.
MultiXactGenWaiting to read or update shared multixact state.
MultiXactMemberBufferWaiting for I/O on a multixact member SLRU buffer.
MultiXactMemberSLRUWaiting to access the multixact member SLRU cache.
MultiXactOffsetBufferWaiting for I/O on a multixact offset SLRU buffer.
MultiXactOffsetSLRUWaiting to access the multixact offset SLRU cache.
MultiXactTruncationWaiting to read or truncate multixact information.
NotifyBufferWaiting for I/O on a NOTIFY message SLRU buffer.
NotifyQueueWaiting to read or update NOTIFY messages.
NotifyQueueTailWaiting to update limit on NOTIFY message storage.
NotifySLRUWaiting to access the NOTIFY message SLRU cache.
OidGenWaiting to allocate a new OID.
OldSnapshotTimeMapWaiting to read or update old snapshot control information.
ParallelAppendWaiting to choose the next subplan during Parallel Append plan execution.
ParallelHashJoinWaiting to synchronize workers during Parallel Hash Join plan execution.
ParallelQueryDSAWaiting for parallel query dynamic shared memory allocation.
PerSessionDSAWaiting for parallel query dynamic shared memory allocation.
PerSessionRecordTypeWaiting to access a parallel query's information about composite types.
PerSessionRecordTypmodWaiting to access a parallel query's information about type modifiers that identify anonymous record types.
PerXactPredicateListWaiting to access the list of predicate locks held by the current serializable transaction during a parallel query.
PredicateLockManagerWaiting to access predicate lock information used by serializable transactions.
ProcArrayWaiting to access the shared per-process data structures (typically, to get a snapshot or report a session's transaction ID).
RelationMappingWaiting to read or update a pg_filenode.map file (used to track the filenode assignments of certain system catalogs).
RelCacheInitWaiting to read or update a pg_internal.init relation cache initialization file.
ReplicationOriginWaiting to create, drop or use a replication origin.
ReplicationOriginStateWaiting to read or update the progress of one replication origin.
ReplicationSlotAllocationWaiting to allocate or free a replication slot.
ReplicationSlotControlWaiting to read or update replication slot state.
ReplicationSlotIOWaiting for I/O on a replication slot.
SerialBufferWaiting for I/O on a serializable transaction conflict SLRU buffer.
SerializableFinishedListWaiting to access the list of finished serializable transactions.
SerializablePredicateListWaiting to access the list of predicate locks held by serializable transactions.
SerializableXactHashWaiting to read or update information about serializable transactions.
SerialSLRUWaiting to access the serializable transaction conflict SLRU cache.
SharedTidBitmapWaiting to access a shared TID bitmap during a parallel bitmap index scan.
SharedTupleStoreWaiting to access a shared tuple store during parallel query.
ShmemIndexWaiting to find or allocate space in shared memory.
SInvalReadWaiting to retrieve messages from the shared catalog invalidation queue.
SInvalWriteWaiting to add a message to the shared catalog invalidation queue.
SubtransBufferWaiting for I/O on a sub-transaction SLRU buffer.
SubtransSLRUWaiting to access the sub-transaction SLRU cache.
SyncRepWaiting to read or update information about the state of synchronous replication.
SyncScanWaiting to select the starting location of a synchronized table scan.
TablespaceCreateWaiting to create or drop a tablespace.
TwoPhaseStateWaiting to read or update the state of prepared transactions.
WALBufMappingWaiting to replace a page in WAL buffers.
WALInsertWaiting to insert WAL data into a memory buffer.
WALWriteWaiting for WAL buffers to be written to disk.
WrapLimitsVacuumWaiting to update limits on transaction id and multixact consumption.
XactBufferWaiting for I/O on a transaction status SLRU buffer.
XactSLRUWaiting to access the transaction status SLRU cache.
XactTruncationWaiting to execute pg_xact_status or update the oldest transaction ID available to it.
XidGenWaiting to allocate a new transaction ID.

참고

Extensions can add LWLock types to the list shown in 표 27.12. In some cases, the name assigned by an extension will not be available in all server processes; so an LWLock wait event might be reported as just extension rather than the extension-assigned name.

표 27.13. Wait Events of Type Timeout

Timeout Wait EventDescription
BaseBackupThrottleWaiting during base backup when throttling activity.
PgSleepWaiting due to a call to pg_sleep or a sibling function.
RecoveryApplyDelayWaiting to apply WAL during recovery because of a delay setting.
RecoveryRetrieveRetryIntervalWaiting during recovery when WAL data is not available from any source (pg_wal, archive or stream).
VacuumDelayWaiting in a cost-based vacuum delay point.

Here is an example of how wait events can be viewed:

SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event is NOT NULL;
 pid  | wait_event_type | wait_event 
------+-----------------+------------
 2540 | Lock            | relation
 6644 | LWLock          | ProcArray
(2 rows)

27.2.4. pg_stat_replication

The pg_stat_replication view will contain one row per WAL sender process, showing statistics about replication to that sender's connected standby server. Only directly connected standbys are listed; no information is available about downstream standby servers.

표 27.14. pg_stat_replication View

Column Type

Description

pid integer

Process ID of a WAL sender process

usesysid oid

OID of the user logged into this WAL sender process

usename name

Name of the user logged into this WAL sender process

application_name text

Name of the application that is connected to this WAL sender

client_addr inet

IP address of the client connected to this WAL sender. If this field is null, it indicates that the client is connected via a Unix socket on the server machine.

client_hostname text

Host name of the connected client, as reported by a reverse DNS lookup of client_addr. This field will only be non-null for IP connections, and only when log_hostname is enabled.

client_port integer

TCP port number that the client is using for communication with this WAL sender, or -1 if a Unix socket is used

backend_start timestamp with time zone

Time when this process was started, i.e., when the client connected to this WAL sender

backend_xmin xid

This standby's xmin horizon reported by hot_standby_feedback.

state text

Current WAL sender state. Possible values are:

  • startup: This WAL sender is starting up.

  • catchup: This WAL sender's connected standby is catching up with the primary.

  • streaming: This WAL sender is streaming changes after its connected standby server has caught up with the primary.

  • backup: This WAL sender is sending a backup.

  • stopping: This WAL sender is stopping.

sent_lsn pg_lsn

Last write-ahead log location sent on this connection

write_lsn pg_lsn

Last write-ahead log location written to disk by this standby server

flush_lsn pg_lsn

Last write-ahead log location flushed to disk by this standby server

replay_lsn pg_lsn

Last write-ahead log location replayed into the database on this standby server

write_lag interval

Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written it (but not yet flushed it or applied it). This can be used to gauge the delay that synchronous_commit level remote_write incurred while committing if this server was configured as a synchronous standby.

flush_lag interval

Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written and flushed it (but not yet applied it). This can be used to gauge the delay that synchronous_commit level on incurred while committing if this server was configured as a synchronous standby.

replay_lag interval

Time elapsed between flushing recent WAL locally and receiving notification that this standby server has written, flushed and applied it. This can be used to gauge the delay that synchronous_commit level remote_apply incurred while committing if this server was configured as a synchronous standby.

sync_priority integer

Priority of this standby server for being chosen as the synchronous standby in a priority-based synchronous replication. This has no effect in a quorum-based synchronous replication.

sync_state text

Synchronous state of this standby server. Possible values are:

  • async: This standby server is asynchronous.

  • potential: This standby server is now asynchronous, but can potentially become synchronous if one of current synchronous ones fails.

  • sync: This standby server is synchronous.

  • quorum: This standby server is considered as a candidate for quorum standbys.

reply_time timestamp with time zone

Send time of last reply message received from standby server


The lag times reported in the pg_stat_replication view are measurements of the time taken for recent WAL to be written, flushed and replayed and for the sender to know about it. These times represent the commit delay that was (or would have been) introduced by each synchronous commit level, if the remote server was configured as a synchronous standby. For an asynchronous standby, the replay_lag column approximates the delay before recent transactions became visible to queries. If the standby server has entirely caught up with the sending server and there is no more WAL activity, the most recently measured lag times will continue to be displayed for a short time and then show NULL.

Lag times work automatically for physical replication. Logical decoding plugins may optionally emit tracking messages; if they do not, the tracking mechanism will simply display NULL lag.

참고

The reported lag times are not predictions of how long it will take for the standby to catch up with the sending server assuming the current rate of replay. Such a system would show similar times while new WAL is being generated, but would differ when the sender becomes idle. In particular, when the standby has caught up completely, pg_stat_replication shows the time taken to write, flush and replay the most recent reported WAL location rather than zero as some users might expect. This is consistent with the goal of measuring synchronous commit and transaction visibility delays for recent write transactions. To reduce confusion for users expecting a different model of lag, the lag columns revert to NULL after a short time on a fully replayed idle system. Monitoring systems should choose whether to represent this as missing data, zero or continue to display the last known value.

27.2.5. pg_stat_wal_receiver

The pg_stat_wal_receiver view will contain only one row, showing statistics about the WAL receiver from that receiver's connected server.

표 27.15. pg_stat_wal_receiver View

Column Type

Description

pid integer

Process ID of the WAL receiver process

status text

Activity status of the WAL receiver process

receive_start_lsn pg_lsn

First write-ahead log location used when WAL receiver is started

receive_start_tli integer

First timeline number used when WAL receiver is started

written_lsn pg_lsn

Last write-ahead log location already received and written to disk, but not flushed. This should not be used for data integrity checks.

flushed_lsn pg_lsn

Last write-ahead log location already received and flushed to disk, the initial value of this field being the first log location used when WAL receiver is started

received_tli integer

Timeline number of last write-ahead log location received and flushed to disk, the initial value of this field being the timeline number of the first log location used when WAL receiver is started

last_msg_send_time timestamp with time zone

Send time of last message received from origin WAL sender

last_msg_receipt_time timestamp with time zone

Receipt time of last message received from origin WAL sender

latest_end_lsn pg_lsn

Last write-ahead log location reported to origin WAL sender

latest_end_time timestamp with time zone

Time of last write-ahead log location reported to origin WAL sender

slot_name text

Replication slot name used by this WAL receiver

sender_host text

Host of the PostgreSQL instance this WAL receiver is connected to. This can be a host name, an IP address, or a directory path if the connection is via Unix socket. (The path case can be distinguished because it will always be an absolute path, beginning with /.)

sender_port integer

Port number of the PostgreSQL instance this WAL receiver is connected to.

conninfo text

Connection string used by this WAL receiver, with security-sensitive fields obfuscated.


27.2.6. pg_stat_subscription

The pg_stat_subscription view will contain one row per subscription for main worker (with null PID if the worker is not running), and additional rows for workers handling the initial data copy of the subscribed tables.

표 27.16. pg_stat_subscription View

Column Type

Description

subid oid

OID of the subscription

subname name

Name of the subscription

pid integer

Process ID of the subscription worker process

relid oid

OID of the relation that the worker is synchronizing; null for the main apply worker

received_lsn pg_lsn

Last write-ahead log location received, the initial value of this field being 0

last_msg_send_time timestamp with time zone

Send time of last message received from origin WAL sender

last_msg_receipt_time timestamp with time zone

Receipt time of last message received from origin WAL sender

latest_end_lsn pg_lsn

Last write-ahead log location reported to origin WAL sender

latest_end_time timestamp with time zone

Time of last write-ahead log location reported to origin WAL sender


27.2.7. pg_stat_ssl

The pg_stat_ssl view will contain one row per backend or WAL sender process, showing statistics about SSL usage on this connection. It can be joined to pg_stat_activity or pg_stat_replication on the pid column to get more details about the connection.

표 27.17. pg_stat_ssl View

Column Type

Description

pid integer

Process ID of a backend or WAL sender process

ssl boolean

True if SSL is used on this connection

version text

Version of SSL in use, or NULL if SSL is not in use on this connection

cipher text

Name of SSL cipher in use, or NULL if SSL is not in use on this connection

bits integer

Number of bits in the encryption algorithm used, or NULL if SSL is not used on this connection

compression boolean

True if SSL compression is in use, false if not, or NULL if SSL is not in use on this connection

client_dn text

Distinguished Name (DN) field from the client certificate used, or NULL if no client certificate was supplied or if SSL is not in use on this connection. This field is truncated if the DN field is longer than NAMEDATALEN (64 characters in a standard build).

client_serial numeric

Serial number of the client certificate, or NULL if no client certificate was supplied or if SSL is not in use on this connection. The combination of certificate serial number and certificate issuer uniquely identifies a certificate (unless the issuer erroneously reuses serial numbers).

issuer_dn text

DN of the issuer of the client certificate, or NULL if no client certificate was supplied or if SSL is not in use on this connection. This field is truncated like client_dn.


27.2.8. pg_stat_gssapi

The pg_stat_gssapi view will contain one row per backend, showing information about GSSAPI usage on this connection. It can be joined to pg_stat_activity or pg_stat_replication on the pid column to get more details about the connection.

표 27.18. pg_stat_gssapi View

Column Type

Description

pid integer

Process ID of a backend

gss_authenticated boolean

True if GSSAPI authentication was used for this connection

principal text

Principal used to authenticate this connection, or NULL if GSSAPI was not used to authenticate this connection. This field is truncated if the principal is longer than NAMEDATALEN (64 characters in a standard build).

encrypted boolean

True if GSSAPI encryption is in use on this connection


27.2.9. pg_stat_archiver

The pg_stat_archiver view will always have a single row, containing data about the archiver process of the cluster.

표 27.19. pg_stat_archiver View

Column Type

Description

archived_count bigint

Number of WAL files that have been successfully archived

last_archived_wal text

Name of the last WAL file successfully archived

last_archived_time timestamp with time zone

Time of the last successful archive operation

failed_count bigint

Number of failed attempts for archiving WAL files

last_failed_wal text

Name of the WAL file of the last failed archival operation

last_failed_time timestamp with time zone

Time of the last failed archival operation

stats_reset timestamp with time zone

Time at which these statistics were last reset


27.2.10. pg_stat_bgwriter

The pg_stat_bgwriter view will always have a single row, containing global data for the cluster.

표 27.20. pg_stat_bgwriter View

Column Type

Description

checkpoints_timed bigint

Number of scheduled checkpoints that have been performed

checkpoints_req bigint

Number of requested checkpoints that have been performed

checkpoint_write_time double precision

Total amount of time that has been spent in the portion of checkpoint processing where files are written to disk, in milliseconds

checkpoint_sync_time double precision

Total amount of time that has been spent in the portion of checkpoint processing where files are synchronized to disk, in milliseconds

buffers_checkpoint bigint

Number of buffers written during checkpoints

buffers_clean bigint

Number of buffers written by the background writer

maxwritten_clean bigint

Number of times the background writer stopped a cleaning scan because it had written too many buffers

buffers_backend bigint

Number of buffers written directly by a backend

buffers_backend_fsync bigint

Number of times a backend had to execute its own fsync call (normally the background writer handles those even when the backend does its own write)

buffers_alloc bigint

Number of buffers allocated

stats_reset timestamp with time zone

Time at which these statistics were last reset


27.2.11. pg_stat_database

The pg_stat_database view will contain one row for each database in the cluster, plus one for shared objects, showing database-wide statistics.

표 27.21. pg_stat_database View

Column Type

Description

datid oid

OID of this database, or 0 for objects belonging to a shared relation

datname name

Name of this database, or NULL for shared objects.

numbackends integer

Number of backends currently connected to this database, or NULL for shared objects. This is the only column in this view that returns a value reflecting current state; all other columns return the accumulated values since the last reset.

xact_commit bigint

Number of transactions in this database that have been committed

xact_rollback bigint

Number of transactions in this database that have been rolled back

blks_read bigint

Number of disk blocks read in this database

blks_hit bigint

Number of times disk blocks were found already in the buffer cache, so that a read was not necessary (this only includes hits in the PostgreSQL buffer cache, not the operating system's file system cache)

tup_returned bigint

Number of rows returned by queries in this database

tup_fetched bigint

Number of rows fetched by queries in this database

tup_inserted bigint

Number of rows inserted by queries in this database

tup_updated bigint

Number of rows updated by queries in this database

tup_deleted bigint

Number of rows deleted by queries in this database

conflicts bigint

Number of queries canceled due to conflicts with recovery in this database. (Conflicts occur only on standby servers; see pg_stat_database_conflicts for details.)

temp_files bigint

Number of temporary files created by queries in this database. All temporary files are counted, regardless of why the temporary file was created (e.g., sorting or hashing), and regardless of the log_temp_files setting.

temp_bytes bigint

Total amount of data written to temporary files by queries in this database. All temporary files are counted, regardless of why the temporary file was created, and regardless of the log_temp_files setting.

deadlocks bigint

Number of deadlocks detected in this database

checksum_failures bigint

Number of data page checksum failures detected in this database (or on a shared object), or NULL if data checksums are not enabled.

checksum_last_failure timestamp with time zone

Time at which the last data page checksum failure was detected in this database (or on a shared object), or NULL if data checksums are not enabled.

blk_read_time double precision

Time spent reading data file blocks by backends in this database, in milliseconds (if track_io_timing is enabled, otherwise zero)

blk_write_time double precision

Time spent writing data file blocks by backends in this database, in milliseconds (if track_io_timing is enabled, otherwise zero)

stats_reset timestamp with time zone

Time at which these statistics were last reset


27.2.12. pg_stat_database_conflicts

The pg_stat_database_conflicts view will contain one row per database, showing database-wide statistics about query cancels occurring due to conflicts with recovery on standby servers. This view will only contain information on standby servers, since conflicts do not occur on master servers.

표 27.22. pg_stat_database_conflicts View

Column Type

Description

datid oid

OID of a database

datname name

Name of this database

confl_tablespace bigint

Number of queries in this database that have been canceled due to dropped tablespaces

confl_lock bigint

Number of queries in this database that have been canceled due to lock timeouts

confl_snapshot bigint

Number of queries in this database that have been canceled due to old snapshots

confl_bufferpin bigint

Number of queries in this database that have been canceled due to pinned buffers

confl_deadlock bigint

Number of queries in this database that have been canceled due to deadlocks


27.2.13. pg_stat_all_tables

The pg_stat_all_tables view will contain one row for each table in the current database (including TOAST tables), showing statistics about accesses to that specific table. The pg_stat_user_tables and pg_stat_sys_tables views contain the same information, but filtered to only show user and system tables respectively.

표 27.23. pg_stat_all_tables View

Column Type

Description

relid oid

OID of a table

schemaname name

Name of the schema that this table is in

relname name

Name of this table

seq_scan bigint

Number of sequential scans initiated on this table

seq_tup_read bigint

Number of live rows fetched by sequential scans

idx_scan bigint

Number of index scans initiated on this table

idx_tup_fetch bigint

Number of live rows fetched by index scans

n_tup_ins bigint

Number of rows inserted

n_tup_upd bigint

Number of rows updated (includes HOT updated rows)

n_tup_del bigint

Number of rows deleted

n_tup_hot_upd bigint

Number of rows HOT updated (i.e., with no separate index update required)

n_live_tup bigint

Estimated number of live rows

n_dead_tup bigint

Estimated number of dead rows

n_mod_since_analyze bigint

Estimated number of rows modified since this table was last analyzed

n_ins_since_vacuum bigint

Estimated number of rows inserted since this table was last vacuumed

last_vacuum timestamp with time zone

Last time at which this table was manually vacuumed (not counting VACUUM FULL)

last_autovacuum timestamp with time zone

Last time at which this table was vacuumed by the autovacuum daemon

last_analyze timestamp with time zone

Last time at which this table was manually analyzed

last_autoanalyze timestamp with time zone

Last time at which this table was analyzed by the autovacuum daemon

vacuum_count bigint

Number of times this table has been manually vacuumed (not counting VACUUM FULL)

autovacuum_count bigint

Number of times this table has been vacuumed by the autovacuum daemon

analyze_count bigint

Number of times this table has been manually analyzed

autoanalyze_count bigint

Number of times this table has been analyzed by the autovacuum daemon


27.2.14. pg_stat_all_indexes

The pg_stat_all_indexes view will contain one row for each index in the current database, showing statistics about accesses to that specific index. The pg_stat_user_indexes and pg_stat_sys_indexes views contain the same information, but filtered to only show user and system indexes respectively.

표 27.24. pg_stat_all_indexes View

Column Type

Description

relid oid

OID of the table for this index

indexrelid oid

OID of this index

schemaname name

Name of the schema this index is in

relname name

Name of the table for this index

indexrelname name

Name of this index

idx_scan bigint

Number of index scans initiated on this index

idx_tup_read bigint

Number of index entries returned by scans on this index

idx_tup_fetch bigint

Number of live table rows fetched by simple index scans using this index


Indexes can be used by simple index scans, bitmap index scans, and the optimizer. In a bitmap scan the output of several indexes can be combined via AND or OR rules, so it is difficult to associate individual heap row fetches with specific indexes when a bitmap scan is used. Therefore, a bitmap scan increments the pg_stat_all_indexes.idx_tup_read count(s) for the index(es) it uses, and it increments the pg_stat_all_tables.idx_tup_fetch count for the table, but it does not affect pg_stat_all_indexes.idx_tup_fetch. The optimizer also accesses indexes to check for supplied constants whose values are outside the recorded range of the optimizer statistics because the optimizer statistics might be stale.

참고

The idx_tup_read and idx_tup_fetch counts can be different even without any use of bitmap scans, because idx_tup_read counts index entries retrieved from the index while idx_tup_fetch counts live rows fetched from the table. The latter will be less if any dead or not-yet-committed rows are fetched using the index, or if any heap fetches are avoided by means of an index-only scan.

27.2.15. pg_statio_all_tables

The pg_statio_all_tables view will contain one row for each table in the current database (including TOAST tables), showing statistics about I/O on that specific table. The pg_statio_user_tables and pg_statio_sys_tables views contain the same information, but filtered to only show user and system tables respectively.

표 27.25. pg_statio_all_tables View

Column Type

Description

relid oid

OID of a table

schemaname name

Name of the schema that this table is in

relname name

Name of this table

heap_blks_read bigint

Number of disk blocks read from this table

heap_blks_hit bigint

Number of buffer hits in this table

idx_blks_read bigint

Number of disk blocks read from all indexes on this table

idx_blks_hit bigint

Number of buffer hits in all indexes on this table

toast_blks_read bigint

Number of disk blocks read from this table's TOAST table (if any)

toast_blks_hit bigint

Number of buffer hits in this table's TOAST table (if any)

tidx_blks_read bigint

Number of disk blocks read from this table's TOAST table indexes (if any)

tidx_blks_hit bigint

Number of buffer hits in this table's TOAST table indexes (if any)


27.2.16. pg_statio_all_indexes

The pg_statio_all_indexes view will contain one row for each index in the current database, showing statistics about I/O on that specific index. The pg_statio_user_indexes and pg_statio_sys_indexes views contain the same information, but filtered to only show user and system indexes respectively.

표 27.26. pg_statio_all_indexes View

Column Type

Description

relid oid

OID of the table for this index

indexrelid oid

OID of this index

schemaname name

Name of the schema this index is in

relname name

Name of the table for this index

indexrelname name

Name of this index

idx_blks_read bigint

Number of disk blocks read from this index

idx_blks_hit bigint

Number of buffer hits in this index


27.2.17. pg_statio_all_sequences

The pg_statio_all_sequences view will contain one row for each sequence in the current database, showing statistics about I/O on that specific sequence.

표 27.27. pg_statio_all_sequences View

Column Type

Description

relid oid

OID of a sequence

schemaname name

Name of the schema this sequence is in

relname name

Name of this sequence

blks_read bigint

Number of disk blocks read from this sequence

blks_hit bigint

Number of buffer hits in this sequence


27.2.18. pg_stat_user_functions

The pg_stat_user_functions view will contain one row for each tracked function, showing statistics about executions of that function. The track_functions parameter controls exactly which functions are tracked.

표 27.28. pg_stat_user_functions View

Column Type

Description

funcid oid

OID of a function

schemaname name

Name of the schema this function is in

funcname name

Name of this function

calls bigint

Number of times this function has been called

total_time double precision

Total time spent in this function and all other functions called by it, in milliseconds

self_time double precision

Total time spent in this function itself, not including other functions called by it, in milliseconds


27.2.19. pg_stat_slru

PostgreSQL accesses certain on-disk information via SLRU (simple least-recently-used) caches. The pg_stat_slru view will contain one row for each tracked SLRU cache, showing statistics about access to cached pages.

표 27.29. pg_stat_slru View

Column Type

Description

name text

Name of the SLRU

blks_zeroed bigint

Number of blocks zeroed during initializations

blks_hit bigint

Number of times disk blocks were found already in the SLRU, so that a read was not necessary (this only includes hits in the SLRU, not the operating system's file system cache)

blks_read bigint

Number of disk blocks read for this SLRU

blks_written bigint

Number of disk blocks written for this SLRU

blks_exists bigint

Number of blocks checked for existence for this SLRU

flushes bigint

Number of flushes of dirty data for this SLRU

truncates bigint

Number of truncates for this SLRU

stats_reset timestamp with time zone

Time at which these statistics were last reset


27.2.20. Statistics Functions

Other ways of looking at the statistics can be set up by writing queries that use the same underlying statistics access functions used by the standard views shown above. For details such as the functions' names, consult the definitions of the standard views. (For example, in psql you could issue \d+ pg_stat_activity.) The access functions for per-database statistics take a database OID as an argument to identify which database to report on. The per-table and per-index functions take a table or index OID. The functions for per-function statistics take a function OID. Note that only tables, indexes, and functions in the current database can be seen with these functions.

Additional functions related to statistics collection are listed in 표 27.30.

표 27.30. Additional Statistics Functions

Function

Description

pg_backend_pid () → integer

Returns the process ID of the server process attached to the current session.

pg_stat_get_activity ( integer ) → setof record

Returns a record of information about the backend with the specified process ID, or one record for each active backend in the system if NULL is specified. The fields returned are a subset of those in the pg_stat_activity view.

pg_stat_get_snapshot_timestamp () → timestamp with time zone

Returns the timestamp of the current statistics snapshot.

pg_stat_clear_snapshot () → void

Discards the current statistics snapshot.

pg_stat_reset () → void

Resets all statistics counters for the current database to zero.

This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_stat_reset_shared ( text ) → void

Resets some cluster-wide statistics counters to zero, depending on the argument. The argument can be bgwriter to reset all the counters shown in the pg_stat_bgwriter view, or archiver to reset all the counters shown in the pg_stat_archiver view.

This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_stat_reset_single_table_counters ( oid ) → void

Resets statistics for a single table or index in the current database to zero.

This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_stat_reset_single_function_counters ( oid ) → void

Resets statistics for a single function in the current database to zero.

This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_stat_reset_slru ( text ) → void

Resets statistics to zero for a single SLRU cache, or for all SLRUs in the cluster. If the argument is NULL, all counters shown in the pg_stat_slru view for all SLRU caches are reset. The argument can be one of CommitTs, MultiXactMember, MultiXactOffset, Notify, Serial, Subtrans, or Xact to reset the counters for only that entry. If the argument is other (or indeed, any unrecognized name), then the counters for all other SLRU caches, such as extension-defined caches, are reset.

This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function.


pg_stat_get_activity, the underlying function of the pg_stat_activity view, returns a set of records containing all the available information about each backend process. Sometimes it may be more convenient to obtain just a subset of this information. In such cases, an older set of per-backend statistics access functions can be used; these are shown in 표 27.31. These access functions use a backend ID number, which ranges from one to the number of currently active backends. The function pg_stat_get_backend_idset provides a convenient way to generate one row for each active backend for invoking these functions. For example, to show the PIDs and current queries of all backends:

SELECT pg_stat_get_backend_pid(s.backendid) AS pid,
       pg_stat_get_backend_activity(s.backendid) AS query
    FROM (SELECT pg_stat_get_backend_idset() AS backendid) AS s;

표 27.31. Per-Backend Statistics Functions

Function

Description

pg_stat_get_backend_idset () → setof integer

Returns the set of currently active backend ID numbers (from 1 to the number of active backends).

pg_stat_get_backend_activity ( integer ) → text

Returns the text of this backend's most recent query.

pg_stat_get_backend_activity_start ( integer ) → timestamp with time zone

Returns the time when the backend's most recent query was started.

pg_stat_get_backend_client_addr ( integer ) → inet

Returns the IP address of the client connected to this backend.

pg_stat_get_backend_client_port ( integer ) → integer

Returns the TCP port number that the client is using for communication.

pg_stat_get_backend_dbid ( integer ) → oid

Returns the OID of the database this backend is connected to.

pg_stat_get_backend_pid ( integer ) → integer

Returns the process ID of this backend.

pg_stat_get_backend_start ( integer ) → timestamp with time zone

Returns the time when this process was started.

pg_stat_get_backend_userid ( integer ) → oid

Returns the OID of the user logged into this backend.

pg_stat_get_backend_wait_event_type ( integer ) → text

Returns the wait event type name if this backend is currently waiting, otherwise NULL. See 표 27.4 for details.

pg_stat_get_backend_wait_event ( integer ) → text

Returns the wait event name if this backend is currently waiting, otherwise NULL. See 표 27.5 through 표 27.13.

pg_stat_get_backend_xact_start ( integer ) → timestamp with time zone

Returns the time when the backend's current transaction was started.