9.26. 系統管理函式
9.26.1. 組態設定函式
Table 9.82 列出了可用於查詢和變更執行階段組態參數的函式。
Table 9.82. Configuration Settings Functions
Name | Return Type | Description |
|
| get current value of setting |
|
| set parameter and return new value |
函數 current_setting 會回傳 setting_name 目前的設定值。它對應於 SQL 指令 SHOW。範例如下:
如果沒有名為 setting_name 的設定,也沒有設定 missing_ok 為 true,則 current_setting 會引發執行錯誤訊息。
set_config 將參數 setting_name 設定為 new_value。如果 is_local 為 true,則新值將僅套用於目前交易事務之中。如果您希望新值套用於目前連線,請讓 is_local 為 false。此功能對應的 SQL 命令為 SET。範例如下:
9.26.2. 伺服器系統信號函數
Table 9.83 中列出的功能將系統控制信號發送到其他伺服器程序。預設情況下,這些功能僅限於超級使用者使用,可以在例外情況使用 GRANT 授予其他人存取權限。
Table 9.83. Server Signaling Functions
Name | Return Type | Description |
|
| 從後端服務取消正在執行的查詢。如果呼叫的角色是其後端被取消的角色的成員或已授予呼叫角色 pg_signal_backend 的角色,則也允許進行這個動作,但是只有超級使用者才能取消超級使用者後端行程。 |
|
| 使伺服器程序重新載入其組態配置檔案 |
|
| 輪流使用下一個伺服器的日誌檔案 |
|
| 終止整個後端程序。如果呼叫的角色是其後端被終止的角色的成員或已授予呼叫角色 pg_signal_backend 的角色,則也允許進行這個動作,但是只有超級使用者才能終止超級使用者的後端程序。 |
如果成功,這些函數均回傳 true,否則回傳 false。
pg_cancel_backend 和 pg_terminate_backend 發送信號(分別為SIGINT 或 SIGTERM)到由程序 ID 指示的後端程序。正在運作中的後端程序 ID 可以從 pg_stat_activity 檢視表的 pid 欄位中找到,或者透過列出伺服器上的 postgres 程序(在 Unix 上使用 ps 或在 Windows 上使用工作管理員)找到。正在執行的後端角色可以在 pg_stat_activity 檢視表的 usename 欄位中找到。
pg_reload_conf 向伺服器發送 SIGHUP 信號,會使所有伺服器程序重新載入組態檔案。
pg_rotate_logfile 指示日誌檔案管理器立即切換到新的輸出檔案。僅當內建的日誌收集器正在運行時,此函數才有作用,因為沒有日誌檔案管理器的子程序可以操作。
9.26.3. Backup Control Functions
The functions shown in Table 9.84 assist in making on-line backups. These functions cannot be executed during recovery (except non-exclusive pg_start_backup
, non-exclusive pg_stop_backup
, pg_is_in_backup
, pg_backup_start_time
and pg_wal_lsn_diff
).
Table 9.84. Backup Control Functions
Name | Return Type | Description |
|
| Create a named point for performing restore (restricted to superusers by default, but other users can be granted EXECUTE to run the function) |
|
| Get current write-ahead log flush location |
|
| Get current write-ahead log insert location |
|
| Get current write-ahead log write location |
|
| Prepare for performing on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function) |
|
| Finish performing exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function) |
|
| Finish performing exclusive or non-exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function) |
|
| True if an on-line exclusive backup is still in progress. |
|
| Get start time of an on-line exclusive backup in progress. |
|
| Force switch to a new write-ahead log file (restricted to superusers by default, but other users can be granted EXECUTE to run the function) |
|
| Convert write-ahead log location to file name |
|
| Convert write-ahead log location to file name and decimal byte offset within file |
|
| Calculate the difference between two write-ahead 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.) When used in exclusive mode, the function writes a backup label file (backup_label
) and, if there are any links in the pg_tblspc/
directory, a tablespace map file (tablespace_map
) into the database cluster's data directory, performs a checkpoint, and then returns the backup's starting write-ahead log location as text. The user can ignore this result value, but it is provided in case it is useful. When used in non-exclusive mode, the contents of these files are instead returned by the pg_stop_backup
function, and should be written to the backup by the caller.
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.
In an exclusive backup, pg_stop_backup
removes the label file and, if it exists, the tablespace_map
file created by pg_start_backup
. In a non-exclusive backup, the contents of the backup_label
and tablespace_map
are returned in the result of the function, and should be written to files in the backup (and not in the data directory). There is an optional second parameter of type boolean
. If false, the pg_stop_backup
will return immediately after the backup is completed without waiting for WAL to be archived. This behavior is only useful for backup software which independently monitors WAL archiving. Otherwise, WAL required to make the backup consistent might be missing and make the backup useless. When this parameter is set to true, pg_stop_backup
will wait for WAL to be archived when archiving is enabled; on the standby, this means that it will wait only when archive_mode = always
. If write activity on the primary is low, it may be useful to run pg_switch_wal
on the primary in order to trigger an immediate segment switch.
When executed on a primary, the function also creates a backup history file in the write-ahead log archive area. The history file includes the label given to pg_start_backup
, the starting and ending write-ahead log locations for the backup, and the starting and ending times of the backup. The return value is the backup's ending write-ahead log location (which again can be ignored). After recording the ending location, the current write-ahead log insertion point is automatically advanced to the next write-ahead log file, so that the ending write-ahead log file can be archived immediately to complete the backup.
pg_switch_wal
moves to the next write-ahead log file, allowing the current file to be archived (assuming you are using continuous archiving). The return value is the ending write-ahead log location + 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, pg_switch_wal
does nothing and returns the start location of the write-ahead log file currently in use.
pg_create_restore_point
creates a named write-ahead log record that can be used as 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.
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 flush location is the location guaranteed 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 both 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 the results of any of the above functions. For example:
Similarly, pg_walfile_name
extracts just the write-ahead log file name. When the given write-ahead log location is exactly at a write-ahead log file boundary, both these functions return the name of the preceding write-ahead log file. This is usually the desired behavior for managing write-ahead log archiving behavior, since the preceding file is the last one that currently needs to be archived.
pg_wal_lsn_diff
calculates the difference in bytes between two write-ahead log locations. It can be used with pg_stat_replication
or some functions shown in Table 9.84 to get the replication lag.
For details about proper usage of these functions, see Section 25.3.
9.26.4. Recovery Control Functions
The functions shown in Table 9.85 provide information about the current status of the standby. These functions may be executed both during recovery and in normal running.
Table 9.85. Recovery Information Functions
Name | Return Type | Description |
|
| True if recovery is still in progress. |
|
| Get last write-ahead 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. |
|
| Get last write-ahead 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. |
|
| 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.86 control the progress of recovery. These functions may be executed only during recovery.
Table 9.86. Recovery Control Functions
Name | Return Type | Description |
|
| True if recovery is paused. |
|
| Promotes a physical standby server. With |
|
| Pauses recovery immediately (restricted to superusers by default, but other users can be granted EXECUTE to run the function). |
|
| Restarts recovery if it was paused (restricted to superusers by default, but other users can be granted EXECUTE to run the function). |
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.
9.26.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.87, and imported with the SET TRANSACTION command.
Table 9.87. Snapshot Synchronization Functions
Name | Return Type | Description |
|
| 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.
9.26.6. Replication Functions
The functions shown in Table 9.88 are for controlling and interacting with replication features. See Section 26.2.5, Section 26.2.6, and Chapter 49 for information about the underlying features. Use of functions for replication origin is restricted to superusers. Use of functions for replication slot is restricted to superusers and users having REPLICATION
privilege.
Many of these functions have equivalent commands in the replication protocol; see Section 52.4.
The functions described in Section 9.26.3, Section 9.26.4, and Section 9.26.5 are also relevant for replication.
Table 9.88. Replication SQL Functions
Function | Return Type | 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 |
|
| Create a replication origin with the given external name, and return the internal id assigned to it. |
|
| Delete a previously created replication origin, including any associated replay progress. |
|
| Lookup a replication origin by name and return the internal id. If no corresponding replication origin is found an error is thrown. |
|
| Mark the current session as replaying from the given origin, allowing replay progress to be tracked. Use |
|
| Cancel the effects of |
|
| Has a replication origin been configured in the current session? |
|
| Return the replay location for the replication origin configured in the current session. The parameter |
|
| Mark 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 previously been configured using |
|
| Cancel the effects of |
|
| Set replication progress for the given node to the given location. This primarily is useful for setting up the initial location or a new location after configuration changes and similar. Be aware that careless use of this function can lead to inconsistently replicated data. |
|
| Return the replay location for the given replication origin. The parameter |
|
| Emit text logical decoding message. This can be used to pass generic messages to logical decoding plugins through WAL. The parameter |
|
| Emit binary logical decoding message. This can be used to pass generic messages to logical decoding plugins through WAL. The parameter |
9.26.7. Database Object Management Functions
Table 9.89 中列出的函數用於計算資料庫物件的磁碟空間使用情況。
Table 9.89. Database Object Size Functions
Name | Return Type | Description |
|
| 欄位用於儲存特定內容的位元組數(可能已壓縮) |
|
| 指定 OID 的資料庫磁碟空間使用情況 |
|
| 指定名稱的資料庫磁碟空間使用情況 |
|
| 指定資料表的索引所使用的磁碟總空間 |
|
| 指定資料表或索引的衍生物件(“ main”,“ fsm”,“ vm”或“ init”)所使用的磁碟空間 |
|
|
|
|
| 將人類可讀格式的大小(以大小單位)轉換為以位元組表示 |
|
| 將以 64 位元整數表示的位元組單位數值轉換為具有量級單位的人類可讀格式 |
|
| 將以數字表示的內容轉換為具有大小單位且適於人類易讀的格式 |
|
| 回傳指定資料表所使用的磁碟空間,不包括索引(但包括 TOAST、free space map 和 visibility map) |
|
| 指定 OID 的資料表空間其所使用的磁碟空間 |
|
| 指定名稱資料表空間所使用的磁碟空間 |
|
| 指定資料所表使用的總磁碟空間,包括所有索引和 TOAST 資料 |
pg_column_size 顯示用於儲存任何單一資料內容的空間。
pg_total_relation_size 接受資料表或 Toast 資料表的 OID 或名稱,回傳用於該資料表的磁碟上總空間,包括所有關聯的索引。此函數等效於 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 和 pg_tablespace_size 接受資料庫或資料表空間的 OID 或名稱,並回傳其中使用的磁碟空間總量。要使用 pg_database_size,您必須對指定的資料庫具有 CONNECT 權限(預設情況下已授予該權限),或者是 pg_read_all_stats 角色的成員。要使用 pg_tablespace_size,您必須對指定的資料表空間具有 CREATE 權限,或者是 pg_read_all_stats 角色的成員,除非它是目前資料庫的預設資料表空間。
pg_relation_size 接受資料表、索引或 Toast 資料表的 OID 或名稱,回傳該關連物件的一個衍生子物件的磁碟大小(以 Byte 為單位)。(請注意,在大多數情況下,使用更上級的函數 pg_total_relation_size 或 pg_table_size會比較方便,這些函數會加總所有衍生子物件的大小。)只使用一個參數的時候,它回傳衍生子物件 main 所佔的磁碟空間的大小。可以提供第二個參數來指定要檢查的衍生子物件:
'main'
returns the size of the main data fork of the relation.'fsm'
returns the size of the Free Space Map (see Section 68.3) associated with the relation.'vm'
returns the size of the Visibility Map (see Section 68.4) associated with the relation.'init'
returns the size of the initialization fork, if any, 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 bytes, kB, MB, GB or TB as appropriate.
pg_size_bytes
can be used to get the size in bytes from a string in human-readable format. The input may have units of bytes, kB, MB, GB or TB, and is parsed case-insensitively. If no units are specified, bytes are assumed.
Note
The units kB, MB, GB and TB used by the functions pg_size_pretty
and pg_size_bytes
are defined using powers of 2 rather than powers of 10, so 1kB is 1024 bytes, 1MB is 10242 = 1048576 bytes, and so on.
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.90 assist in identifying the specific disk files associated with database objects.
Table 9.90. Database Object Location Functions
Name | Return Type | Description |
|
| Filenode number of the specified relation |
|
| File path name of the specified relation |
|
| Find the relation associated with a given tablespace and filenode |
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 68.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.
pg_filenode_relation
is the reverse of pg_relation_filenode
. Given a “tablespace” OID and a “filenode”, it returns the associated relation's OID. For a table in the database's default tablespace, the tablespace can be specified as 0.
Table 9.91 lists functions used to manage collations.
Table 9.91. Collation Management Functions
Name | Return Type | Description |
|
| Return actual version of collation from operating system |
|
| Import operating system collations |
pg_collation_actual_version
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 pg_collation.collversion
, then objects depending on the collation might need to be rebuilt. See also ALTER COLLATION.
pg_import_system_collations
adds collations to the system catalog pg_collation
based on all the locales it finds in the operating system. This is what initdb
uses; see Section 23.2.2 for more details. If additional locales are installed into the operating system later on, this function can be run again to add collations for the new locales. Locales that match existing entries in pg_collation
will be skipped. (But collation objects based on locales that are no longer present in the operating system are not removed by this function.) The schema
parameter would typically be pg_catalog
, but that is not a requirement; the collations could be installed into some other schema as well. The function returns the number of new collation objects it created.
Table 9.92. Partitioning Information Functions
Name | Return Type | Description |
|
| List information about tables or indexes in a partition tree for a given partitioned table or partitioned index, with one row for each partition. Information provided includes the name of the partition, the name of its immediate parent, a boolean value telling if the partition is a leaf, and an integer telling its level in the hierarchy. The value of level begins at |
|
| List the ancestor relations of the given partition, including the partition itself. |
|
| Return the top-most parent of a partition tree to which the given relation belongs. |
To check the total size of the data contained in measurement
table described in Section 5.11.2.1, one could use the following query:
9.26.8. Index Maintenance Functions
Table 9.93 shows the functions available for index maintenance tasks. These functions cannot be executed during recovery. Use of these functions is restricted to superusers and the owner of the given index.
Table 9.93. Index Maintenance Functions
Name | Return Type | Description |
|
| summarize page ranges not already summarized |
|
| summarize the page range covering the given block, if not already summarized |
|
| de-summarize the page range covering the given block, if summarized |
|
| move GIN pending list entries into main index structure |
brin_summarize_new_values
accepts the OID or name of a BRIN index and inspects the 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 the table pages. It returns the number of new page range summaries that were inserted into the index. brin_summarize_range
does the same, except it only summarizes the range that covers the given block number.
gin_clean_pending_list
accepts the OID or name of a GIN index and cleans up the pending list of the specified index by moving entries in it to the main GIN data structure in bulk. It returns the number of pages removed from the pending list. Note that if the argument is a GIN index built with the fastupdate
option disabled, no cleanup happens and the return value is 0, because the index doesn't have a pending list. Please see Section 66.4.1 and Section 66.5 for details of the pending list and fastupdate
option.
9.26.9. Generic File Access Functions
The functions shown in Table 9.94 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 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 which the database can read and that those reads bypass all in-database privilege checks. This means that, among other things, a user with this access is able to read the contents of the pg_authid
table where authentication information is contained, as well as read any file in the database. Therefore, granting access to these functions should be carefully considered.
Table 9.94. Generic File Access Functions
Name | Return Type | Description |
|
| List the contents of a directory. Restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
|
| List the name, size, and last modification time of files in the log directory. Access is granted to members of the |
|
| List the name, size, and last modification time of files in the WAL directory. Access is granted to members of the |
|
| List the name, size, and last modification time of files in the WAL archive status directory. Access is granted to members of the |
|
| List the name, size, and last modification time of files in the temporary directory for |
|
| Return the contents of a text file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
|
| Return the contents of a file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
|
| Return information about a file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function. |
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 (except pg_ls_dir
, which returns an empty result set). If false
, an error is raised. The default is false
.
pg_ls_dir
returns the names of all files (and directories and other special files) in the specified directory. The include_dot_dirs
indicates whether “.” and “..” are included in the result set. The default is to exclude them (false
), but including them can be useful when missing_ok
is true
, to distinguish an empty directory from an non-existent directory.
pg_ls_logdir
returns the name, size, and last modified time (mtime) of each file in the log directory. By default, only superusers and members of the pg_monitor
role can use this function. Access may be granted to others using GRANT
.
pg_ls_waldir
returns the name, size, and last modified time (mtime) of each file in the write ahead log (WAL) directory. By default only superusers and members of the pg_monitor
role can use this function. Access may be granted to others using GRANT
.
pg_ls_archive_statusdir
returns the name, size, and last modified time (mtime) of each file in the WAL archive status directory pg_wal/archive_status
. By default only superusers and members of the pg_monitor
role can use this function. Access may be granted to others using GRANT
.
pg_ls_tmpdir
returns the name, size, and last modified time (mtime) of each file in the temporary file directory for the specified tablespace
. If tablespace
is not provided, the pg_default
tablespace is used. By default only superusers and members of the pg_monitor
role can use this function. Access may be granted to others using GRANT
.
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:
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:
9.26.10. Advisory Lock Functions
The functions shown in Table 9.95 manage advisory locks. For details about proper use of these functions, see Section 13.3.5.
Table 9.95. Advisory Lock Functions
Name | Return Type | Description |
|
| Obtain exclusive session level advisory lock |
|
| Obtain exclusive session level advisory lock |
|
| Obtain shared session level advisory lock |
|
| Obtain shared session level advisory lock |
|
| Release an exclusive session level advisory lock |
|
| Release an exclusive session level advisory lock |
|
| Release all session level advisory locks held by the current session |
|
| Release a shared session level advisory lock |
|
| Release a shared session level advisory lock |
|
| Obtain exclusive transaction level advisory lock |
|
| Obtain exclusive transaction level advisory lock |
|
| Obtain shared transaction level advisory lock |
|
| Obtain shared transaction level advisory lock |
|
| Obtain exclusive session level advisory lock if available |
|
| Obtain exclusive session level advisory lock if available |
|
| Obtain shared session level advisory lock if available |
|
| Obtain shared session level advisory lock if available |
|
| Obtain exclusive transaction level advisory lock if available |
|
| Obtain exclusive transaction level advisory lock if available |
|
| Obtain shared transaction level advisory lock if available |
|
| 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.
Last updated