PostgreSQL 9.3.25 Documentation | ||||
---|---|---|---|---|
Prev | Up | Chapter 9. Functions and Operators | Next |
The functions described in this section are used to control and monitor a PostgreSQL installation.
Table 9-59 shows the functions available to query and alter run-time configuration parameters.
Table 9-59. Configuration Settings Functions
Name | Return Type | Description |
---|---|---|
current_setting(setting_name) |
text | get current value of setting |
set_config(setting_name,
new_value, is_local) |
text | set parameter and return new value |
The function current_setting
yields the current value of the setting setting_name. It corresponds to the
SQL command SHOW. An example:
SELECT current_setting('datestyle'); current_setting ----------------- ISO, MDY (1 row)
set_config
sets the parameter
setting_name to new_value. If is_local
is true, the new value will only apply to
the current transaction. If you want the new value to apply for the
current session, use false instead. The
function corresponds to the SQL command SET. An example:
SELECT set_config('log_statement_stats', 'off', false); set_config ------------ off (1 row)
The functions shown in Table 9-60 send control signals to other server processes. Use of these functions is usually restricted to superusers, with noted exceptions.
Table 9-60. Server Signaling Functions
Name | Return Type | Description |
---|---|---|
pg_cancel_backend(pid
int) |
boolean | Cancel a backend's current query. You can execute this against another backend that has exactly the same role as the user calling the function. In all other cases, you must be a superuser. |
pg_reload_conf() |
boolean | Cause server processes to reload their configuration files |
pg_rotate_logfile() |
boolean | Rotate server's log file |
pg_terminate_backend(pid
int) |
boolean | Terminate a backend. You can execute this against another backend that has exactly the same role as the user calling the function. In all other cases, you must be a superuser. |
Each of these functions returns true if successful and false otherwise.
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_reload_conf
sends a
SIGHUP signal to the server,
causing configuration files to be reloaded by all server
processes.
pg_rotate_logfile
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.
The functions shown in Table 9-61
assist in making on-line backups. These functions cannot be
executed during recovery (except pg_is_in_backup
, pg_backup_start_time
and pg_xlog_location_diff
).
Table 9-61. Backup Control Functions
Name | Return Type | Description |
---|---|---|
pg_create_restore_point(name
text) |
text | Create a named point for performing restore (restricted to superusers) |
pg_current_xlog_insert_location() |
text | Get current transaction log insert location |
pg_current_xlog_location() |
text | Get current transaction log write location |
pg_start_backup(label
text [, fast boolean
]) |
text | Prepare for performing on-line backup (restricted to superusers or replication roles) |
pg_stop_backup() |
text | Finish performing on-line backup (restricted to superusers or replication roles) |
pg_is_in_backup() |
bool | True if an on-line exclusive backup is still in progress. |
pg_backup_start_time() |
timestamp with time zone | Get start time of an on-line exclusive backup in progress. |
pg_switch_xlog() |
text | Force switch to a new transaction log file (restricted to superusers) |
pg_xlogfile_name(location
text) |
text | Convert transaction log location string to file name |
pg_xlogfile_name_offset(location text) |
text, integer | Convert transaction log location string to file name and decimal byte offset within file |
pg_xlog_location_diff(location text, location text) |
numeric | Calculate the difference between two transaction log locations |
pg_start_backup
accepts an
arbitrary user-defined label for the backup. (Typically this would
be the name under which the backup dump file will be stored.) The
function writes a backup label file (backup_label) into the database cluster's data
directory, performs a checkpoint, and then returns the backup's
starting transaction log location as text. The user can ignore this
result value, but it is provided in case it is useful.
postgres=# select pg_start_backup('label_goes_here'); pg_start_backup ----------------- 0/D4445B8 (1 row)
There is an optional second parameter of type boolean. If true, it specifies
executing pg_start_backup
as quickly
as possible. This forces an immediate checkpoint which will cause a
spike in I/O operations, slowing any concurrently executing
queries.
pg_stop_backup
removes the label
file created by pg_start_backup
, and
creates a backup history file in the transaction log archive area.
The history file includes the label given to pg_start_backup
, the starting and ending
transaction log locations for the backup, and the starting and
ending times of the backup. The return value is the backup's ending
transaction log location (which again can be ignored). After
recording the ending location, the current transaction log
insertion point is automatically advanced to the next transaction
log file, so that the ending transaction log file can be archived
immediately to complete the backup.
pg_switch_xlog
moves to the next
transaction log file, allowing the current file to be archived
(assuming you are using continuous archiving). The return value is
the ending transaction log location + 1 within the just-completed
transaction log file. If there has been no transaction log activity
since the last transaction log switch, pg_switch_xlog
does nothing and returns the start
location of the transaction log file currently in use.
pg_create_restore_point
creates a
named transaction log record that can be used as recovery target,
and returns the corresponding transaction 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.
pg_current_xlog_location
displays
the current transaction log write location in the same format used
by the above functions. Similarly, pg_current_xlog_insert_location
displays the
current transaction log insertion point. The insertion point is the
"logical" end of the transaction log at
any instant, while the write location is the end of what has
actually been written out from the server's internal buffers. 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 transaction log files. The insertion
point is made available primarily for server debugging purposes.
These are both read-only operations and do not require superuser
permissions.
You can use pg_xlogfile_name_offset
to extract the
corresponding transaction log file name and byte offset from the
results of any of the above functions. For example:
postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup()); file_name | file_offset --------------------------+------------- 00000001000000000000000D | 4039624 (1 row)
Similarly, pg_xlogfile_name
extracts just the transaction log file name. When the given
transaction log location is exactly at a transaction log file
boundary, both these functions return the name of the preceding
transaction log file. This is usually the desired behavior for
managing transaction log archiving behavior, since the preceding
file is the last one that currently needs to be archived.
pg_xlog_location_diff
calculates
the difference in bytes between two transaction log locations. It
can be used with pg_stat_replication or
some functions shown in Table 9-61
to get the replication lag.
For details about proper usage of these functions, see Section 24.3.
The functions shown in Table 9-62 provide information about the current status of the standby. These functions may be executed both during recovery and in normal running.
Table 9-62. Recovery Information Functions
Name | Return Type | Description |
---|---|---|
pg_is_in_recovery() |
bool | True if recovery is still in progress. |
pg_last_xlog_receive_location() |
text | Get last transaction log location received and synced to disk by streaming replication. While streaming replication is in progress this will increase monotonically. If recovery has completed this will remain static at the value of the last WAL record received and synced to disk during recovery. If streaming replication is disabled, or if it has not yet started, the function returns NULL. |
pg_last_xlog_replay_location() |
text | Get last transaction log location replayed during recovery. If recovery is still in progress this will increase monotonically. If recovery has completed then this value will remain static at the value of the last WAL record applied during that recovery. When the server has been started normally without recovery the function returns NULL. |
pg_last_xact_replay_timestamp() |
timestamp with time zone | Get time stamp of last transaction replayed during recovery. This is the time at which the commit or abort WAL record for that transaction was generated on the primary. If no transactions have been replayed during recovery, this function returns NULL. Otherwise, if recovery is still in progress this will increase monotonically. If recovery has completed then this value will remain static at the value of the last transaction applied during that recovery. When the server has been started normally without recovery the function returns NULL. |
The functions shown in Table 9-63 control the progress of recovery. These functions may be executed only during recovery.
Table 9-63. Recovery Control Functions
Name | Return Type | Description |
---|---|---|
pg_is_xlog_replay_paused() |
bool | True if recovery is paused. |
pg_xlog_replay_pause() |
void | Pauses recovery immediately. |
pg_xlog_replay_resume() |
void | Restarts recovery if it was paused. |
While recovery is paused no further database changes are applied. If in hot standby, all new queries will see the same consistent snapshot of the database, and no further query conflicts will be generated until recovery is resumed.
If streaming replication is disabled, the paused state may continue indefinitely without problem. While streaming replication is in progress 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.
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-64, and imported with the SET TRANSACTION command.
Table 9-64. Snapshot Synchronization Functions
Name | Return Type | Description |
---|---|---|
pg_export_snapshot() |
text | Save the current snapshot and return its identifier |
The function pg_export_snapshot
saves the current snapshot and returns a text
string identifying the snapshot. This string must be passed
(outside the database) to clients that want to import the snapshot.
The snapshot is available for import only until the end of the
transaction that exported it. A transaction can export more than
one snapshot, if needed. Note that doing so is only useful in
READ COMMITTED transactions, since in
REPEATABLE READ and higher isolation
levels, transactions use the same snapshot throughout their
lifetime. Once a transaction has exported any snapshots, it cannot
be prepared with PREPARE
TRANSACTION.
See SET TRANSACTION for details of how to use an exported snapshot.
The functions shown in Table 9-65 calculate the disk space usage of database objects.
Table 9-65. Database Object Size Functions
Name | Return Type | Description |
---|---|---|
pg_column_size(any) |
int | Number of bytes used to store a particular value (possibly compressed) |
pg_database_size(oid) |
bigint | Disk space used by the database with the specified OID |
pg_database_size(name) |
bigint | Disk space used by the database with the specified name |
pg_indexes_size(regclass) |
bigint | Total disk space used by indexes attached to the specified table |
pg_relation_size(relation
regclass, fork
text) |
bigint | Disk space used by the specified fork ('main', 'fsm', 'vm', or 'init') of the specified table or index |
pg_relation_size(relation
regclass) |
bigint | Shorthand for pg_relation_size(..., 'main') |
pg_size_pretty(bigint) |
text | Converts a size in bytes expressed as a 64-bit integer into a human-readable format with size units |
pg_size_pretty(numeric) |
text | Converts a size in bytes expressed as a numeric value into a human-readable format with size units |
pg_table_size(regclass) |
bigint | Disk space used by the specified table, excluding indexes (but including TOAST, free space map, and visibility map) |
pg_tablespace_size(oid) |
bigint | Disk space used by the tablespace with the specified OID |
pg_tablespace_size(name) |
bigint | Disk space used by the tablespace with the specified name |
pg_total_relation_size(regclass) |
bigint | Total disk space used by the specified table, including all indexes and TOAST data |
pg_column_size
shows the space
used to store any individual data value.
pg_total_relation_size
accepts the
OID or name of a table or toast table, and returns the total
on-disk space used for that table, including all associated
indexes. This function is equivalent to pg_table_size
+
pg_indexes_size
.
pg_table_size
accepts the OID or
name of a table and returns the disk space needed for that table,
exclusive of indexes. (TOAST space, free space map, and visibility
map are included.)
pg_indexes_size
accepts the OID or
name of a table and returns the total disk space used by all the
indexes attached to that table.
pg_database_size
and pg_tablespace_size
accept the OID or name of a
database or tablespace, and return the total disk space used
therein. To use pg_database_size
, you
must have CONNECT permission on the
specified database (which is granted by default). To use
pg_tablespace_size
, you must have
CREATE permission on the specified
tablespace, unless it is the default tablespace for the current
database.
pg_relation_size
accepts the OID
or name of a table, index or toast table, and returns the on-disk
size in bytes of one fork of that relation. (Note that for most
purposes it is more convenient to use the higher-level functions
pg_total_relation_size
or
pg_table_size
, which sum the sizes of
all forks.) With one argument, it returns the size of the main data
fork of the relation. The second argument can be provided to
specify which fork to examine:
'main' returns the size of the main data fork of the relation.
'fsm' returns the size of the Free Space Map (see Section 58.3) associated with the relation.
'vm' returns the size of the Visibility Map (see Section 58.4) associated with the relation.
'init' returns the size of the initialization fork, if any, (see Section 58.5) associated with the relation.
pg_size_pretty
can be used to
format the result of one of the other functions in a human-readable
way, using kB, MB, GB or TB as appropriate.
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. Just write the table name enclosed in single quotes so that it looks like a literal constant. For compatibility with the handling of ordinary SQL names, the string will be converted to lower case unless it contains double quotes around the table name.
If an OID that does not represent an existing object is passed as argument to one of the above functions, NULL is returned.
The functions shown in Table 9-66 assist in identifying the specific disk files associated with database objects.
Table 9-66. Database Object Location Functions
Name | Return Type | Description |
---|---|---|
pg_relation_filenode(relation
regclass) |
oid | Filenode number of the specified relation |
pg_relation_filepath(relation
regclass) |
text | File path name of the specified relation |
pg_relation_filenode
accepts the
OID or name of a table, index, sequence, or toast table, and
returns the "filenode" number currently
assigned to it. The filenode is the base component of the file
name(s) used for the relation (see Section 58.1 for more information).
For most tables the result is the same as pg_class.relfilenode, but for certain system catalogs
relfilenode is zero and this function
must be used to get the correct value. The function returns NULL if
passed a relation that does not have storage, such as a view.
pg_relation_filepath
is similar to
pg_relation_filenode
, but it returns
the entire file path name (relative to the database cluster's data
directory PGDATA) of the relation.
The functions shown in Table 9-67 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. Use a relative path for files in the cluster directory, and a path matching the log_directory configuration setting for log files. Use of these functions is restricted to superusers.
Table 9-67. Generic File Access Functions
Name | Return Type | Description |
---|---|---|
pg_ls_dir(dirname text) |
setof text | List the contents of a directory |
pg_read_file(filename
text [, offset
bigint, length
bigint]) |
text | Return the contents of a text file |
pg_read_binary_file(filename
text [, offset
bigint, length
bigint]) |
bytea | Return the contents of a file |
pg_stat_file(filename
text) |
record | Return information about a file |
pg_ls_dir
returns all the names in
the specified directory, except the special entries "." and "..".
pg_read_file
returns part of a
text file, starting at the given offset,
returning at most length bytes (less if
the end of file is reached first). If offset is negative, it is relative to the end of
the file. If offset and length are omitted, the entire file is returned.
The bytes read from the file are interpreted as a string in the
server encoding; an error is thrown if they are not valid in that
encoding.
pg_read_binary_file
is similar to
pg_read_file
, except that the result
is a bytea value; accordingly, no encoding
checks are performed. In combination with the convert_from
function, this function can be used
to read a file in a specified encoding:
SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
pg_stat_file
returns a record
containing the file size, last accessed time stamp, last modified
time stamp, last file status change time stamp (Unix platforms
only), file creation time stamp (Windows only), and a boolean indicating if it is a directory. Typical usages
include:
SELECT * FROM pg_stat_file('filename'); SELECT (pg_stat_file('filename')).modification;
The functions shown in Table 9-68 manage advisory locks. For details about proper use of these functions, see Section 13.3.4.
Table 9-68. Advisory Lock Functions
Name | Return Type | Description |
---|---|---|
pg_advisory_lock(key
bigint) |
void | Obtain exclusive session level advisory lock |
pg_advisory_lock(key1
int, key2
int) |
void | Obtain exclusive session level advisory lock |
pg_advisory_lock_shared(key
bigint) |
void | Obtain shared session level advisory lock |
pg_advisory_lock_shared(key1
int, key2
int) |
void | Obtain shared session level advisory lock |
pg_advisory_unlock(key
bigint) |
boolean | Release an exclusive session level advisory lock |
pg_advisory_unlock(key1
int, key2
int) |
boolean | Release an exclusive session level advisory lock |
pg_advisory_unlock_all() |
void | Release all session level advisory locks held by the current session |
pg_advisory_unlock_shared(key
bigint) |
boolean | Release a shared session level advisory lock |
pg_advisory_unlock_shared(key1 int, key2 int) |
boolean | Release a shared session level advisory lock |
pg_advisory_xact_lock(key
bigint) |
void | Obtain exclusive transaction level advisory lock |
pg_advisory_xact_lock(key1
int, key2
int) |
void | Obtain exclusive transaction level advisory lock |
pg_advisory_xact_lock_shared(key bigint) |
void | Obtain shared transaction level advisory lock |
pg_advisory_xact_lock_shared(key1 int, key2 int) |
void | Obtain shared transaction level advisory lock |
pg_try_advisory_lock(key
bigint) |
boolean | Obtain exclusive session level advisory lock if available |
pg_try_advisory_lock(key1
int, key2
int) |
boolean | Obtain exclusive session level advisory lock if available |
pg_try_advisory_lock_shared(key bigint) |
boolean | Obtain shared session level advisory lock if available |
pg_try_advisory_lock_shared(key1 int, key2 int) |
boolean | Obtain shared session level advisory lock if available |
pg_try_advisory_xact_lock(key
bigint) |
boolean | Obtain exclusive transaction level advisory lock if available |
pg_try_advisory_xact_lock(key1 int, key2 int) |
boolean | Obtain exclusive transaction level advisory lock if available |
pg_try_advisory_xact_lock_shared(key bigint) |
boolean | Obtain shared transaction level advisory lock if available |
pg_try_advisory_xact_lock_shared(key1 int, key2 int) |
boolean | Obtain shared transaction level advisory lock if available |
pg_advisory_lock
locks an
application-defined resource, 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
lock on the same resource identifier, this function will wait until
the resource becomes available. The lock is exclusive. Multiple
lock requests stack, so that if the same resource is locked three
times it must then be unlocked three times to be released for other
sessions' use.
pg_advisory_lock_shared
works the
same as pg_advisory_lock
, except the
lock can be shared with other sessions requesting shared locks.
Only would-be exclusive lockers are locked out.
pg_try_advisory_lock
is similar to
pg_advisory_lock
, except the function
will not wait for the lock to become available. It will either
obtain the lock immediately and return true, or return false if
the lock cannot be acquired immediately.
pg_try_advisory_lock_shared
works
the same as pg_try_advisory_lock
,
except it attempts to acquire a shared rather than an exclusive
lock.
pg_advisory_unlock
will release a
previously-acquired exclusive session level advisory lock. It
returns true if the lock is successfully
released. If the lock was not held, it will return false, and in addition, an SQL warning will be
reported by the server.
pg_advisory_unlock_shared
works
the same as pg_advisory_unlock
,
except it releases a shared session level advisory lock.
pg_advisory_unlock_all
will
release all session level advisory locks held by the current
session. (This function is implicitly invoked at session end, even
if the client disconnects ungracefully.)
pg_advisory_xact_lock
works the
same as pg_advisory_lock
, except the
lock is automatically released at the end of the current
transaction and cannot be released explicitly.
pg_advisory_xact_lock_shared
works
the same as pg_advisory_lock_shared
,
except the lock is automatically released at the end of the current
transaction and cannot be released explicitly.
pg_try_advisory_xact_lock
works
the same as pg_try_advisory_lock
,
except the lock, if acquired, is automatically released at the end
of the current transaction and cannot be released explicitly.
pg_try_advisory_xact_lock_shared
works the same as pg_try_advisory_lock_shared
, except the lock, if
acquired, is automatically released at the end of the current
transaction and cannot be released explicitly.