DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH PRINT BOOK
 

9.20. System Administration Functions

Table 9-45 shows the functions available to query and alter run-time configuration parameters.

Table 9-45. Configuration Settings Functions

NameReturn TypeDescription
current_setting(setting_name) textcurrent value of setting
set_config(setting_name, new_value, is_local) textset 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-46 send control signals to other server processes. Use of these functions is restricted to superusers.

Table 9-46. Server Signalling Functions

NameReturn TypeDescription
pg_cancel_backend(pid int) booleanCancel a backend's current query
pg_reload_conf() booleanCause server processes to reload their configuration files
pg_rotate_logfile() booleanRotate server's log file

Each of these functions returns true if successful and false otherwise.

pg_cancel_backend sends a query cancel (SIGINT) signal to a backend process identified by process ID. The process ID of an active backend can be found from the procpid column in the pg_stat_activity view, or by listing the postgres processes on the server with ps.

pg_reload_conf sends a SIGHUP signal to the server, causing the 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 redirect_stderr is used for logging, since otherwise there is no log-file manager subprocess.

The functions shown in Table 9-47 assist in making on-line backups. Use of the first three functions is restricted to superusers.

Table 9-47. Backup Control Functions

NameReturn TypeDescription
pg_start_backup(label text) textSet up for performing on-line backup
pg_stop_backup() textFinish performing on-line backup
pg_switch_xlog() textForce switch to a new transaction log file
pg_current_xlog_location() textGet current transaction log write location
pg_current_xlog_insert_location() textGet current transaction log insert location
pg_xlogfile_name_offset(location text) text, integerConvert transaction log location string to file name and decimal byte offset within file
pg_xlogfile_name(location text) textConvert transaction log location string to file name

pg_start_backup accepts a single parameter which is 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 into the database cluster's data directory, and then returns the backup's starting transaction log location as text. The user need not pay any attention to this result value, but it is provided in case it is of use.

postgres=# select pg_start_backup('label_goes_here');
 pg_start_backup
-----------------
 0/D4445B8
(1 row)

pg_stop_backup removes the label file created by pg_start_backup, and instead 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 may be of little interest). After noting 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 result is the ending transaction log location 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 end location of the previous transaction log file.

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 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 transction log location is exactly at an 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.

For details about proper usage of these functions, see Section 23.3.

The functions shown in Table 9-48 calculate the actual disk space usage of database objects.

Table 9-48. Database Object Size Functions

NameReturn TypeDescription
pg_column_size(any)intNumber of bytes used to store a particular value (possibly compressed)
pg_database_size(oid) bigintDisk space used by the database with the specified OID
pg_database_size(name) bigintDisk space used by the database with the specified name
pg_relation_size(oid) bigintDisk space used by the table or index with the specified OID
pg_relation_size(text) bigint Disk space used by the table or index with the specified name. The table name may be qualified with a schema name
pg_size_pretty(bigint) textConverts a size in bytes into a human-readable format with size units
pg_tablespace_size(oid) bigintDisk space used by the tablespace with the specified OID
pg_tablespace_size(name) bigintDisk space used by the tablespace with the specified name
pg_total_relation_size(oid) bigint Total disk space used by the table with the specified OID, including indexes and toasted data
pg_total_relation_size(text) bigint Total disk space used by the table with the specified name, including indexes and toasted data. The table name may be qualified with a schema name

pg_column_size shows the space used to store any individual data value.

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.

pg_relation_size accepts the OID or name of a table, index or toast table, and returns the size in bytes.

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.

pg_total_relation_size accepts the OID or name of a table or toast table, and returns the size in bytes of the data and all associated indexes and toast tables.

The functions shown in Table 9-49 provide native file access to files on the machine hosting the server. Only files within the database cluster directory and the log_directory may be accessed. Use a relative path for files within 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-49. Generic File Access Functions

NameReturn TypeDescription
pg_ls_dir(dirname text) setof textList the contents of a directory
pg_read_file(filename text, offset bigint, length bigint) textReturn the contents of a text file
pg_stat_file(filename text) recordReturn 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.

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-50 manage advisory locks. For details about proper usage of these functions, see Section 12.3.4.

Table 9-50. Advisory Lock Functions

NameReturn TypeDescription
pg_advisory_lock(key bigint) voidObtain exclusive advisory lock
pg_advisory_lock(key1 int, key2 int) voidObtain exclusive advisory lock
pg_advisory_lock_shared(key bigint) voidObtain shared advisory lock
pg_advisory_lock_shared(key1 int, key2 int) voidObtain shared advisory lock
pg_try_advisory_lock(key bigint) booleanObtain exclusive advisory lock if available
pg_try_advisory_lock(key1 int, key2 int) booleanObtain exclusive advisory lock if available
pg_try_advisory_lock_shared(key bigint) booleanObtain shared advisory lock if available
pg_try_advisory_lock_shared(key1 int, key2 int) booleanObtain shared advisory lock if available
pg_advisory_unlock(key bigint) booleanRelease an exclusive advisory lock
pg_advisory_unlock(key1 int, key2 int) booleanRelease an exclusive advisory lock
pg_advisory_unlock_shared(key bigint) booleanRelease a shared advisory lock
pg_advisory_unlock_shared(key1 int, key2 int) booleanRelease a shared advisory lock
pg_advisory_unlock_all() voidRelease all advisory locks held by the current session

pg_advisory_lock locks an application-defined resource, which may 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, the 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 be also 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 now.

pg_try_advisory_lock_shared works the same as pg_try_advisory_lock, except it attempts to acquire shared rather than exclusive lock.

pg_advisory_unlock will release a previously-acquired exclusive advisory lock. It will return true if the lock is successfully released. If the lock was in fact not held, it will return false, and in addition, an SQL warning will be raised by the server.

pg_advisory_unlock_shared works the same as pg_advisory_unlock, except to release a shared advisory lock.

pg_advisory_unlock_all will release all advisory locks held by the current session. (This function is implicitly invoked at session end, even if the client disconnects ungracefully.)