9.28. System Administration Functions
- 9.28.1. Configuration Settings Functions
- 9.28.2. Server Signaling Functions
- 9.28.3. Backup Control Functions
- 9.28.4. Recovery Control Functions
- 9.28.5. Snapshot Synchronization Functions
- 9.28.6. Replication Management Functions
- 9.28.7. Database Object Management Functions
- 9.28.8. Index Maintenance Functions
- 9.28.9. Generic File Access Functions
- 9.28.10. Advisory Lock Functions
The functions described in this section are used to control and monitor a PostgreSQL installation.
9.28.1. Configuration Settings Functions #
Table 9.93 shows the functions available to query and alter run-time configuration parameters.
Table 9.93. Configuration Settings Functions
Function Description Example(s) |
---|
Returns the current value of the
setting
|
Sets the parameter
|
9.28.2. Server Signaling Functions #
The functions shown in
Table 9.94
send control signals to
other server processes. Use of these functions is restricted to
superusers by default but access may be granted to others using
GRANT
, with noted exceptions.
Each of these functions returns
true
if
the signal was successfully sent and
false
if sending the signal failed.
Table 9.94. Server Signaling Functions
Function Description |
---|
Cancels the current query of the session whose backend process has the
specified process ID. This is also allowed if the
calling role is a member of the role whose backend is being canceled or
the calling role has privileges of
|
Requests to log the memory contexts of the backend with the
specified process ID. This function can send the request to
backends and auxiliary processes except logger. These memory contexts
will be logged at
|
Causes all processes of the
PostgreSQL
server to reload their configuration files. (This is initiated by
sending a
SIGHUP
signal to the postmaster
process, which in turn sends
SIGHUP
to each
of its children.) You can use the
|
Signals the log-file manager to switch to a new output file immediately. This works only when the built-in log collector is running, since otherwise there is no log-file manager subprocess. |
Terminates the session whose backend process has the
specified process ID. This is also allowed if the calling role
is a member of the role whose backend is being terminated or the
calling role has privileges of
If
|
pg_cancel_backend
and
pg_terminate_backend
send signals (
SIGINT
or
SIGTERM
respectively) to backend processes identified by process ID.
The process ID of an active backend can be found from
the
pid
column of the
pg_stat_activity
view, or by listing the
postgres
processes on the server (using
ps
on Unix or the
Task
Manager
on
Windows
).
The role of an active backend can be found from the
usename
column of the
pg_stat_activity
view.
pg_log_backend_memory_contexts
can be used
to log the memory contexts of a backend process. For example:
postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid()); pg_log_backend_memory_contexts -------------------------------- t (1 row)
One message for each memory context will be logged. For example:
LOG: logging memory contexts of PID 10377 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid()); LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used ... LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used
If there are more than 100 child contexts under the same parent, the first 100 child contexts are logged, along with a summary of the remaining contexts. Note that frequent calls to this function could incur significant overhead, because it may generate a large number of log messages.
9.28.3. Backup Control Functions #
The functions shown in
Table 9.95
assist in making on-line backups.
These functions cannot be executed during recovery (except
pg_backup_start
,
pg_backup_stop
,
and
pg_wal_lsn_diff
).
For details about proper usage of these functions, see Section 25.3 .
Table 9.95. Backup Control Functions
Function Description |
---|
Creates a named marker record in the write-ahead log that can later be used as a recovery target, and returns the corresponding write-ahead log location. The given name can then be used with recovery_target_name to specify the point up to which recovery will proceed. Avoid creating multiple restore points with the same name, since recovery will stop at the first one whose name matches the recovery target. This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
Returns the current write-ahead log flush location (see notes below). |
Returns the current write-ahead log insert location (see notes below). |
Returns the current write-ahead log write location (see notes below). |
Prepares the server to begin an on-line backup. The only required
parameter is an arbitrary user-defined label for the backup.
(Typically this would be the name under which the backup dump file
will be stored.)
If the optional second parameter is given as
This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
Finishes performing an on-line backup. The desired contents of the backup label file and the tablespace map file are returned as part of the result of the function and must be written to files in the backup area. These files must not be written to the live data directory (doing so will cause PostgreSQL to fail to restart in the event of a crash).
There is an optional parameter of type
When executed on a primary, this function also creates a backup
history file in the write-ahead log archive area. The history file
includes the label given to
The result of the function is a single record.
The
This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
Forces the server to switch to a new write-ahead log file, which
allows the current file to be archived (assuming you are using
continuous archiving). The result is the ending write-ahead log
location plus 1 within the just-completed write-ahead log file. If
there has been no write-ahead log activity since the last write-ahead
log switch,
This function is restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
Converts a write-ahead log location to the name of the WAL file holding that location. |
Converts a write-ahead log location to a WAL file name and byte offset within that file. |
Extracts the sequence number and timeline ID from a WAL file name. |
Calculates the difference in bytes (
|
pg_current_wal_lsn
displays the current write-ahead
log write location in the same format used by the above functions.
Similarly,
pg_current_wal_insert_lsn
displays the
current write-ahead log insertion location
and
pg_current_wal_flush_lsn
displays the current
write-ahead log flush location. The insertion location is
the
"
logical
"
end of the write-ahead log at any instant,
while the write location is the end of what has actually been written out
from the server's internal buffers, and the flush location is the last
location known to be written to durable storage. The write location is the
end of what can be examined from outside the server, and is usually what
you want if you are interested in archiving partially-complete write-ahead
log files. The insertion and flush locations are made available primarily
for server debugging purposes. These are all read-only operations and do
not require superuser permissions.
You can use
pg_walfile_name_offset
to extract the
corresponding write-ahead log file name and byte offset from
a
pg_lsn
value. For example:
postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn); file_name | file_offset --------------------------+------------- 00000001000000000000000D | 4039624 (1 row)
Similarly,
pg_walfile_name
extracts just the write-ahead log file name.
pg_split_walfile_name
is useful to compute a
LSN
from a file offset and WAL file name, for example:
postgres=# \set file_name '000000010000000100C000AB' postgres=# \set offset 256 postgres=# SELECT '0/0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn FROM pg_split_walfile_name(:'file_name') pd, pg_show_all_settings() ps WHERE ps.name = 'wal_segment_size'; lsn --------------- C001/AB000100 (1 row)
9.28.4. Recovery Control Functions #
The functions shown in Table 9.96 provide information about the current status of a standby server. These functions may be executed both during recovery and in normal running.
Table 9.96. Recovery Information Functions
The functions shown in Table 9.97 control the progress of recovery. These functions may be executed only during recovery.
Table 9.97. Recovery Control Functions
pg_wal_replay_pause
and
pg_wal_replay_resume
cannot be executed while
a promotion is ongoing. If a promotion is triggered while recovery
is paused, the paused state ends and promotion continues.
If streaming replication is disabled, the paused state may continue indefinitely without a problem. If streaming replication is in progress then WAL records will continue to be received, which will eventually fill available disk space, depending upon the duration of the pause, the rate of WAL generation and available disk space.
9.28.5. Snapshot Synchronization Functions #
PostgreSQL
allows database sessions to synchronize their
snapshots. A
snapshot
determines which data is visible to the
transaction that is using the snapshot. Synchronized snapshots are
necessary when two or more sessions need to see identical content in the
database. If two sessions just start their transactions independently,
there is always a possibility that some third transaction commits
between the executions of the two
START TRANSACTION
commands,
so that one session sees the effects of that transaction and the other
does not.
To solve this problem, PostgreSQL allows a transaction to export the snapshot it is using. As long as the exporting transaction remains open, other transactions can import its snapshot, and thereby be guaranteed that they see exactly the same view of the database that the first transaction sees. But note that any database changes made by any one of these transactions remain invisible to the other transactions, as is usual for changes made by uncommitted transactions. So the transactions are synchronized with respect to pre-existing data, but act normally for changes they make themselves.
Snapshots are exported with the
pg_export_snapshot
function,
shown in
Table 9.98
, and
imported with the
SET TRANSACTION
command.
Table 9.98. Snapshot Synchronization Functions
Function Description |
---|
Saves the transaction's current snapshot and returns
a
A transaction can export more than one snapshot, if needed. Note that
doing so is only useful in
|
Take a snapshot of running transactions and write it to WAL, without having to wait for bgwriter or checkpointer to log one. This is useful for logical decoding on standby, as logical slot creation has to wait until such a record is replayed on the standby. |
9.28.6. Replication Management Functions #
The functions shown
in
Table 9.99
are for
controlling and interacting with replication features.
See
Section 26.2.5
,
Section 26.2.6
, and
Chapter 48
for information about the underlying features.
Use of functions for replication origin is only allowed to the
superuser by default, but may be allowed to other users by using the
GRANT
command.
Use of functions for replication slots is restricted to superusers
and users having
REPLICATION
privilege.
Many of these functions have equivalent commands in the replication protocol; see Section 53.4 .
The functions described in Section 9.28.3 , Section 9.28.4 , and Section 9.28.5 are also relevant for replication.
Table 9.99. Replication Management Functions
Function Description |
---|
Creates a new physical replication slot named
|
Drops the physical or logical replication slot
named
|
Creates a new logical (decoding) replication slot named
|
Copies an existing physical replication slot named
|
Copies an existing logical replication slot
named
|
Returns changes in the slot
|
Behaves just like
the
|
Behaves just like
the
|
Behaves just like
the
|
Advances the current confirmed position of a replication slot named
|
Creates a replication origin with the given external name, and returns the internal ID assigned to it. |
Deletes a previously-created replication origin, including any associated replay progress. |
Looks up a replication origin by name and returns the internal ID. If
no such replication origin is found,
|
Marks the current session as replaying from the given
origin, allowing replay progress to be tracked.
Can only be used if no origin is currently selected.
Use
|
Cancels the effects
of
|
Returns true if a replication origin has been selected in the current session. |
Returns the replay location for the replication origin selected in
the current session. The parameter
|
Marks the current transaction as replaying a transaction that has
committed at the given
LSN
and timestamp. Can
only be called when a replication origin has been selected
using
|
Cancels the effects of
|
Sets replication progress for the given node to the given location. This is primarily useful for setting up the initial location, or setting a new location after configuration changes and similar. Be aware that careless use of this function can lead to inconsistently replicated data. |
Returns the replay location for the given replication origin. The
parameter
|
Emits a logical decoding message. This can be used to pass generic
messages to logical decoding plugins through
WAL. The
|
Synchronize the logical failover replication slots from the primary
server to the standby server. This function can only be executed on the
standby server. Temporary synced slots, if any, cannot be used for
logical decoding and must be dropped after promotion. See
Section 47.2.3
for details.
Note that this function cannot be executed if
Caution
If, after executing the function,
|
9.28.7. Database Object Management Functions #
The functions shown in
Table 9.100
calculate
the disk space usage of database objects, or assist in presentation
or understanding of usage results.
bigint
results
are measured in bytes. If an OID that does
not represent an existing object is passed to one of these
functions,
NULL
is returned.
Table 9.100. Database Object Size Functions
Function Description |
---|
Shows the number of bytes used to store any individual data value. If applied directly to a table column value, this reflects any compression that was done. |
Shows the compression algorithm that was used to compress
an individual variable-length value. Returns
|
Shows the
|
Computes the total disk space used by the database with the specified
name or OID. To use this function, you must
have
|
Computes the total disk space used by indexes attached to the specified table. |
Computes the disk space used by one
"
fork
"
of the
specified relation. (Note that for most purposes it is more
convenient to use the higher-level
functions
|
Converts a size in human-readable format (as returned
by
|
Converts a size in bytes into a more easily human-readable format with size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes, 1MB is 1024 2 = 1048576 bytes, and so on. |
Computes the disk space used by the specified table, excluding indexes (but including its TOAST table if any, free space map, and visibility map). |
Computes the total disk space used in the tablespace with the
specified name or OID. To use this function, you must
have
|
Computes the total disk space used by the specified table, including
all indexes and
TOAST
data. The result is
equivalent to
|
The functions above that operate on tables or indexes accept a
regclass
argument, which is simply the OID of the table or index
in the
pg_class
system catalog. You do not have to look up
the OID by hand, however, since the
regclass
data type's input
converter will do the work for you. See
Section 8.19
for details.
The functions shown in Table 9.101 assist in identifying the specific disk files associated with database objects.
Table 9.101. Database Object Location Functions
Function Description |
---|
Returns the
"
filenode
"
number currently assigned to the
specified relation. The filenode is the base component of the file
name(s) used for the relation (see
Section 65.1
for more information).
For most relations the result is the same as
|
Returns the entire file path name (relative to the database cluster's
data directory,
|
Returns a relation's OID given the tablespace OID and filenode it is
stored under. This is essentially the inverse mapping of
|
Table 9.102 lists functions used to manage collations.
Table 9.102. Collation Management Functions
Function Description |
---|
Returns the actual version of the collation object as it is currently
installed in the operating system. If this is different from the
value in
|
Returns the actual version of the database's collation as it is currently
installed in the operating system. If this is different from the
value in
|
Adds collations to the system
catalog
|
Table 9.103 lists functions that provide information about the structure of partitioned tables.
Table 9.103. Partitioning Information Functions
For example, to check the total size of the data contained in a
partitioned table
measurement
, one could use the
following query:
SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size FROM pg_partition_tree('measurement');
9.28.8. Index Maintenance Functions #
Table 9.104 shows the functions available for index maintenance tasks. (Note that these maintenance tasks are normally done automatically by autovacuum; use of these functions is only required in special cases.) These functions cannot be executed during recovery. Use of these functions is restricted to superusers and the owner of the given index.
Table 9.104. Index Maintenance Functions
Function Description |
---|
Scans the specified BRIN index to find page ranges in the base table that are not currently summarized by the index; for any such range it creates a new summary index tuple by scanning those table pages. Returns the number of new page range summaries that were inserted into the index. |
Summarizes the page range covering the given block, if not already
summarized. This is
like
|
Removes the BRIN index tuple that summarizes the page range covering the given table block, if there is one. |
Cleans up the
"
pending
"
list of the specified GIN index
by moving entries in it, in bulk, to the main GIN data structure.
Returns the number of pages removed from the pending list.
If the argument is a GIN index built with
the
|
9.28.9. Generic File Access Functions #
The functions shown in
Table 9.105
provide native access to
files on the machine hosting the server. Only files within the
database cluster directory and the
log_directory
can be
accessed, unless the user is a superuser or is granted the role
pg_read_server_files
. Use a relative path for files in
the cluster directory, and a path matching the
log_directory
configuration setting for log files.
Note that granting users the EXECUTE privilege on
pg_read_file()
, or related functions, allows them the
ability to read any file on the server that the database server process can
read; these functions bypass all in-database privilege checks. This means
that, for example, a user with such access is able to read the contents of
the
pg_authid
table where authentication
information is stored, as well as read any table data in the database.
Therefore, granting access to these functions should be carefully
considered.
When granting privilege on these functions, note that the table entries
showing optional parameters are mostly implemented as several physical
functions with different parameter lists. Privilege must be granted
separately on each such function, if it is to be
used.
psql
's
\df
command
can be useful to check what the actual function signatures are.
Some of these functions take an optional
missing_ok
parameter, which specifies the behavior when the file or directory does
not exist. If
true
, the function
returns
NULL
or an empty result set, as appropriate.
If
false
, an error is raised. (Failure conditions
other than
"
file not found
"
are reported as errors in any
case.) The default is
false
.
Table 9.105. Generic File Access Functions
9.28.10. Advisory Lock Functions #
The functions shown in Table 9.106 manage advisory locks. For details about proper use of these functions, see Section 13.3.5 .
All these functions are intended to be used to lock application-defined
resources, which can be identified either by a single 64-bit key value or
two 32-bit key values (note that these two key spaces do not overlap).
If another session already holds a conflicting lock on the same resource
identifier, the functions will either wait until the resource becomes
available, or return a
false
result, as appropriate for
the function.
Locks can be either shared or exclusive: a shared lock does not conflict
with other shared locks on the same resource, only with exclusive locks.
Locks can be taken at session level (so that they are held until released
or the session ends) or at transaction level (so that they are held until
the current transaction ends; there is no provision for manual release).
Multiple session-level lock requests stack, so that if the same resource
identifier is locked three times there must then be three unlock requests
to release the resource in advance of session end.
Table 9.106. Advisory Lock Functions