PostgreSQL 正體中文使用手冊
PostgreSQL.TW官方使用手冊小島故事加入社團
11
11
  • 簡介
  • 前言
    • 1. 什麼是PostgreSQL?
    • 2. PostgreSQL沿革
    • 3. 慣例
    • 4. 其他參考資訊
    • 5. 問題回報指南
  • I. 新手教學
    • 1. 入門指南
      • 1.1. 安裝
      • 1.2. 基礎架構
      • 1.3. 建立一個資料庫
      • 1.4. 存取一個資料庫
    • 2. SQL查詢語言
      • 2.1. 簡介
      • 2.2. 概念
      • 2.3. 創建一個新的資料表
      • 2.4. 資料列是資料表的組成單位
      • 2.5. 資料表的查詢
      • 2.6. 交叉查詢
      • 2.7. 彙總查詢
      • 2.8. 更新資料
      • 2.9. 刪除資料
    • 3. 先進功能
      • 3.1. 簡介
      • 3.2. 檢視表(View)
      • 3.3. 外部索引鍵
      • 3.4. 交易安全
      • 3.5. 窗函數
      • 3.6. 繼承
      • 3.7. 結論
  • II. SQL查詢語言
    • 4. SQL語法
      • 4.1. 語法結構
      • 4.2. 參數表示式
      • 4.3. 函數呼叫
    • 5. 定義資料結構
      • 5.1. 認識資料表
      • 5.2. 預設值
      • 5.3. 限制條件
      • 5.4. 系統欄位
      • 5.5. 表格變更
      • 5.6. 權限
      • 5.7. 資料列安全原則
      • 5.8. Schemas
      • 5.9. 繼承
      • 5.10. 分割資料表
      • 5.11. 外部資料
      • 5.12. 其他資料庫物件
      • 5.13. 相依性追蹤
    • 6. 資料處理
      • 6.1. 新增資料
      • 6.2. 更新資料
      • 6.3. 刪除資料
      • 6.4. 修改並回傳資料
    • 7. 資料查詢
      • 7.1. 概觀
      • 7.2. 資料表表示式
      • 7.3. 取得資料列表
      • 7.4. 合併查詢結果
      • 7.5. 資料排序
      • 7.6. 指定資料範圍
      • 7.7. 列舉資料
      • 7.8. 遞迴查詢(Common Table Expressions)
    • 8. 資料型別
      • 8.1. 數字型別
      • 8.2. 貨幣型別
      • 8.3. 字串型別
      • 8.4. 位元組型別(bytea)
      • 8.5. 日期時間型別
      • 8.6. 布林型別
      • 8.7. 列舉型別
      • 8.8. 地理資訊型別
      • 8.9. 網路資訊型別
      • 8.10. 位元字串型別
      • 8.11. 全文檢索型別
      • 8.12. UUID型別
      • 8.13. XML型別
      • 8.14. JSON型別
      • 8.15. 陣列
      • 8.16. 複合型別
      • 8.17. 範圍型別
      • 8.18. 指標型別
      • 8.19. pg_lsn型別
      • 8.20. 概念型別
    • 9. 函式及運算子
      • 9.1. 邏輯運算子
      • 9.2. 比較函式及運算子
      • 9.3. 數學函式及運算子
      • 9.4. 字串函式及運算子
      • 9.5. 位元字串函式及運算子
      • 9.6. 二元字串函式及運算子
      • 9.7. 特徵比對
      • 9.8. 型別轉換函式
      • 9.9 日期時間函式及運算子
      • 9.10. 列舉型別函式
      • 9.11. 地理資訊函式及運算子
      • 9.12. 網路位址函式及運算子
      • 9.13. 文字檢索函式及運算子
      • 9.14. XML函式
      • 9.15. JSON函式及運算子
      • 9.16. 序列函式
      • 9.17. 條件表示式
      • 9.18. 陣列函式及運算子
      • 9.19. 範圍函式及運算子
      • 9.20. 彙總函數
      • 9.21. Window函式
      • 9.22. 子查詢
      • 9.23. 資料列與陣列的比較運算
      • 9.24. 集合回傳函式
      • 9.25. 系統資訊函數
      • 9.26. 系統管理函式
      • 9.27. 觸發函式
      • 9.28. 事件觸發函式
    • 10. 型別轉換
      • 10.1. 概觀
      • 10.2. 運算子
      • 10.3. 函式
      • 10.4. 資料儲存轉換規則
      • 10.5. UNION、CASE 等相關結構
      • 10.6. SELECT輸出規則
    • 11. 索引(Index)
      • 11.1. 簡介
      • 11.2. 索引型別
      • 11.3. 多欄位索引
      • 11.4. 索引與ORDER BY
      • 11.5. 善用多個索引
      • 11.6. 唯一值索引
      • 11.7. 表示式索引
      • 11.8. 部份索引(partial index)
      • 11.9. 運算子物件及家族
      • 11.10. 索引與排序規則
      • 11.11. 索引限定查詢(Index-only scan)
      • 11.12. 檢查索引運用
    • 12. 全文檢索
      • 12.1. 簡介
      • 12.2. 查詢與索引
      • 12.3. 細部控制
      • 12.4. 延伸功能
      • 12.5. 斷詞
      • 12.6. 字典
      • 12.7. 組態範例
      • 12.8. 測試與除錯
      • 12.9. GIN及GiST索引型別
      • 12.10. psql支援
      • 12.11. 功能限制
    • 13. 一致性管理(MVCC)
      • 13.1. 簡介
      • 13.2. 交易隔離
      • 13.3. 鎖定模式
      • 13.4. 在應用端檢視資料一致性
      • 13.5. 特別注意
      • 13.6. 鎖定與索引
    • 14. 效能技巧
      • 14.1. 善用EXPLAIN
      • 14.2. 統計資訊
      • 14.3. 使用確切的JOIN方式
      • 14.4. 快速建立資料庫內容
      • 14.5. 彈性設定
    • 15. 平行查詢
      • 15.1. 如何運作?
      • 15.2. 啓用時機?
      • 15.3. 平行查詢計畫
      • 15.4. 平行查詢的安全性
  • III. 系統管理
    • 16. 用原始碼安裝
      • 16.1. Short Version
      • 16.2. Requirements
      • 16.3. Getting The Source
      • 16.4. 安裝流程
      • 16.5. Post-Installation Setup
      • 16.6. Supported Platforms
      • 16.7. 平台相關的注意事項
    • 17. 用原始碼在 Windows 上安裝
      • 17.1. Building with Visual C++ or the Microsoft Windows SDK
    • 18. 服務配置與維運
      • 18.1. PostgreSQL 使用者帳號
      • 18.2. Creating a Database Cluster
      • 18.3. Starting the Database Server
      • 18.4. 核心資源管理
      • 18.5. Shutting Down the Server
      • 18.6. Upgrading a PostgreSQL Cluster
      • 18.7. Preventing Server Spoofing
      • 18.8. Encryption Options
      • 18.9. Secure TCP/IP Connections with SSL
      • 18.10. Secure TCP/IP Connections with SSH Tunnels
      • 18.11. 在 Windows 註冊事件日誌
    • 19. 服務組態設定
      • 19.1. Setting Parameters
      • 19.2. File Locations
      • 19.3. 連線與認證
      • 19.4. 資源配置
      • 19.5. Write Ahead Log
      • 19.6. 複寫(Replication)
      • 19.7. 查詢規畫
      • 19.8. 錯誤回報與日誌記錄
      • 19.9. Run-time Statistics
      • 19.10. 自動資料庫清理
      • 19.11. 用戶端連線預設參數
      • 19.12. 交易鎖定管理
      • 19.13. 版本與平台的相容性
      • 19.14. Error Handling
      • 19.15. 預先配置的參數
      • 19.16. Customized Options
      • 19.17. Developer Options
      • 19.18. Short Options
    • 20. 使用者認證
      • 20.1. 設定檔:pg_hba.conf
      • 20.2. User Name Maps
      • 20.3. Authentication Methods
      • 20.4. Authentication Problems
    • 21. 資料庫角色
      • 21.1. Database Roles
      • 21.2. Role Attributes
      • 21.3. Role Membership
      • 21.4. 移除角色
      • 21.5. Default Roles
      • 21.6. Function Security
    • 22. Managing Databases
      • 22.1. Overview
      • 22.2. Creating a Database
      • 22.3. 樣版資料庫
      • 22.4. Database Configuration
      • 22.5. Destroying a Database
      • 22.6. Tablespaces
    • 23. 語系
      • 23.1. 語系支援
      • 23.2. Collation Support
      • 23.3. 字元集支援
    • 24. 例行性資料庫維護工作
      • 24.1. 例行性資料清理
      • 24.2. 定期重建索引
      • 24.3. Log File Maintenance
    • 25. 備份及還原
      • 25.1. SQL Dump
      • 25.2. File System Level Backup
      • 25.3. Continuous Archiving and Point-in-Time Recovery (PITR)
    • 26. High Availability, Load Balancing, and Replication
      • 26.1. Comparison of Different Solutions
      • 26.2. 日誌轉送備用伺服器 Log-Shipping Standby Servers
      • 26.3. Failover
      • 26.4. Alternative Method for Log Shipping
      • 26.5. Hot Standby
    • 27. Recovery Configuration
      • 27.1. Archive Recovery Settings
      • 27.2. Recovery Target Settings
      • 27.3. Standby Server Settings
    • 28. 監控資料庫活動
      • 28.1. Standard Unix Tools
      • 28.2. 統計資訊收集器
      • 28.3. Viewing Locks
      • 28.4. Progress Reporting
      • 28.5. Dynamic Tracing
    • 29. Monitoring Disk Usage
      • 29.1. Determining Disk Usage
      • 29.2. Disk Full Failure
    • 30. 高可靠度及預寫日誌
      • 30.1. Reliability
      • 30.2. Write-Ahead Logging (WAL)
      • 30.3. Asynchronous Commit
      • 30.4. WAL Configuration
      • 30.5. WAL Internals
    • 31. 邏輯複寫(Logical Replication)
      • 31.1. 發佈(Publication)
      • 31.2. 訂閱(Subscription)
      • 31.3. 衝突處理
      • 31.4. 限制
      • 31.5. 架構
      • 31.6. 監控
      • 31.7. 安全性
      • 31.8. 系統設定
      • 31.9. 快速設定
    • 32. Just-in-Time Compilation (JIT)
      • 32.1. What is JIT compilation?
      • 32.2. When to JIT?
      • 32.3. Configuration
      • 32.4. Extensibility
    • 33. 迴歸測試
      • 33.1. Running the Tests
      • 33.2. Test Evaluation
      • 33.3. Variant Comparison Files
      • 33.4. TAP Tests
      • 33.5. Test Coverage Examination
  • IV. 用戶端介面
    • 34. libpq - C Library
      • 34.1. 資料庫連線控制函數
      • 34.2. 連線狀態函數
      • 34.3. Command Execution Functions
      • 34.4. Asynchronous Command Processing
      • 34.5. Retrieving Query Results Row-By-Row
      • 34.6. Canceling Queries in Progress
      • 34.7. The Fast-Path Interface
      • 34.8. Asynchronous Notification
      • 34.9. Functions Associated with the COPY Command
      • 34.10. Control Functions
      • 34.11. Miscellaneous Functions
      • 34.12. Notice Processing
      • 34.13. Event System
      • 34.14. 環境變數
      • 34.15. 密碼檔
      • 34.16. The Connection Service File
      • 34.17. LDAP Lookup of Connection Parameters
      • 34.18. SSL Support
      • 34.19. Behavior in Threaded Programs
      • 34.20. Building libpq Programs
      • 34.21. Example Programs
    • 35. Large Objects
      • 35.1. Introduction
      • 35.2. Implementation Features
      • 35.3. Client Interfaces
      • 35.4. Server-side Functions
      • 35.5. Example Program
    • 36. ECPG - Embedded SQL in C
      • 36.1. The Concept
      • 36.2. Managing Database Connections
      • 36.3. Running SQL Commands
      • 36.4. Using Host Variables
      • 36.5. Dynamic SQL
      • 36.6. pgtypes Library
      • 36.7. Using Descriptor Areas
      • 36.8. Error Handling
      • 36.9. Preprocessor Directives
      • 36.10. Processing Embedded SQL Programs
      • 36.11. Library Functions
      • 36.12. Large Objects
      • 36.13. C++ Applications
      • 36.14. Embedded SQL Commands
      • 36.15. Informix Compatibility Mode
      • 36.16. Internals
    • 37. The Information Schema
      • 37.1. The Schema
      • 37.2. Data Types
      • 37.3. information_schema_catalog_name
      • 37.4. administrable_role_authorizations
      • 37.5. applicable_roles
      • 37.6. attributes
      • 37.7. character_sets
      • 37.8. check_constraint_routine_usage
      • 37.9. check_constraints
      • 37.10. collations
      • 37.11. collation_character_set_applicability
      • 37.12. column_domain_usage
      • 37.13. column_options
      • 37.14. column_privileges
      • 37.15. column_udt_usage
      • 37.16. columns
      • 37.17. constraint_column_usage
      • 37.18. constraint_table_usage
      • 37.19. data_type_privileges
      • 37.20. domain_constraints
      • 37.21. domain_udt_usage
      • 37.22. domains
      • 37.23. element_types
      • 37.24. enabled_roles
      • 37.25. foreign_data_wrapper_options
      • 37.26. foreign_data_wrappers
      • 37.27. foreign_server_options
      • 37.28. foreign_servers
      • 37.29. foreign_table_options
      • 37.30. foreign_tables
      • 37.31. key_column_usage
      • 37.32. parameters
      • 37.33. referential_constraints
      • 37.34. role_column_grants
      • 37.35. role_routine_grants
      • 37.36. role_table_grants
      • 37.37. role_udt_grants
      • 37.38. role_usage_grants
      • 37.39. routine_privileges
      • 37.40. routines
      • 37.41. schemata
      • 37.42. sequences
      • 37.43. sql_features
      • 37.44. sql_implementation_info
      • 37.45. sql_languages
      • 37.46. sql_packages
      • 37.47. sql_parts
      • 37.48. sql_sizing
      • 37.49. sql_sizing_profiles
      • 37.50. table_constraints
      • 37.51. table_privileges
      • 37.52. tables
      • 37.53. transforms
      • 37.54. triggered_update_columns
      • 37.55. triggers
      • 37.56. udt_privileges
      • 37.57. usage_privileges
      • 37.58. user_defined_types
      • 37.59. user_mapping_options
      • 37.60. user_mappings
      • 37.61. view_column_usage
      • 37.62. view_routine_usage
      • 37.63. view_table_usage
      • 37.64. views
  • V. 資料庫程式設計
    • 38. SQL 延伸功能
      • 38.1. How Extensibility Works
      • 38.2. The PostgreSQL Type System
      • 38.3. 使用者自訂函數
      • 38.4. User-defined Procedures
      • 38.5. Query Language (SQL) Functions
      • 38.6. Function Overloading
      • 38.7. 函數易變性類別
      • 38.8. Procedural Language Functions
      • 38.9. Internal Functions
      • 38.10. C-Language Functions
      • 38.11. User-defined Aggregates
      • 38.12. User-defined Types
      • 38.13. User-defined Operators
      • 38.14. Operator Optimization Information
      • 38.15. Interfacing Extensions To Indexes
      • 38.16. Packaging Related Objects into an Extension
      • 38.17. Extension Building Infrastructure
    • 39. Triggers
    • 40. Event Triggers
    • 41. 規則系統
      • 41.1. The Query Tree
      • 41.2. Views and the Rule System
      • 41.3. Materialized Views
      • 41.4. Rules on INSERT, UPDATE, and DELETE
      • 41.5. 規則及權限
      • 41.6. Rules and Command Status
      • 41.7. Rules Versus Triggers
    • 42. Procedural Languages(程序語言)
      • 42.1. Installing Procedural Languages
    • 43. PL/pgSQL - SQL Procedural Language
      • 43.5. 基本語法
    • 44. PL/Tcl - Tcl Procedural Language
    • 45. PL/Perl - Perl Procedural Language
    • 46. PL/Python - Python Procedural Language
    • 47. Server Programming Interface
    • 48. Background Worker Processes
    • 49. Logical Decoding
    • 50. Replication Progress Tracking
  • VI. 參考資訊
    • I. SQL 指令
      • ALTER DATABASE
      • ALTER DEFAULT PRIVILEGES
      • ALTER EXTENSION
      • ALTER FUNCTION
      • ALTER INDEX
      • ALTER LANGUAGE
      • ALTER MATERIALIZED VIEW
      • ALTER POLICY
      • ALTER PUBLICATION
      • ALTER ROLE
      • ALTER RULE
      • ALTER SCHEMA
      • ALTER SEQUENCE
      • ALTER STATISTICS
      • ALTER SUBSCRIPTION
      • ALTER TABLE
      • ALTER TABLESPACE
      • ALTER TRIGGER
      • ALTER TYPE
      • ALTER VIEW
      • ANALYZE
      • CLUSTER
      • COMMENT
      • COPY
      • CREATE CAST
      • CREATE DATABASE
      • CREATE EXTENSION
      • CREATE FOREIGN TABLE
      • CREATE FOREIGN DATA WRAPPER
      • CREATE FUNCTION
      • CREATE INDEX
      • CREATE LANGUAGE
      • CREATE MATERIALIZED VIEW
      • CREATE DOMAIN
      • CREATE POLICY
      • CREATE PROCEDURE
      • CREATE PUBLICATION
      • CREATE ROLE
      • CREATE RULE
      • CREATE SCHEMA
      • CREATE SEQUENCE
      • CREATE SERVER
      • CREATE STATISTICS
      • CREATE SUBSCRIPTION
      • CREATE TABLE
      • CREATE TABLE AS
      • CREATE TABLESPACE
      • CREATE TRANSFORM
      • CREATE TRIGGER
      • CREATE TYPE
      • CREATE USER
      • CREATE USER MAPPING
      • CREATE VIEW
      • DELETE
      • DO
      • DROP DATABASE
      • DROP EXTENSION
      • DROP FUNCTION
      • DROP INDEX
      • DROP LANGUAGE
      • DROP MATERIALIZED VIEW
      • DROP OWNED
      • DROP POLICY
      • DROP ROLE
      • DROP RULE
      • DROP SCHEMA
      • DROP SEQUENCE
      • DROP STATISTICS
      • DROP SUBSCRIPTION
      • DROP TABLE
      • DROP TABLESPACE
      • DROP TRANSFORM
      • DROP TRIGGER
      • DROP TYPE
      • DROP USER
      • DROP VIEW
      • EXECUTE
      • EXPLAIN
      • GRANT
      • IMPORT FOREIGN SCHEMA
      • INSERT
      • LISTEN
      • LOAD
      • NOTIFY
      • PREPARE TRANSACTION
      • REASSIGN OWNED
      • REFRESH MATERIALIZED VIEW
      • REINDEX
      • RESET
      • REVOKE
      • SELECT
      • SELECT INTO
      • SET
      • SET CONSTRAINTS
      • SET ROLE
      • SET SESSION AUTHORIZATION
      • SET TRANSACTION
      • SHOW
      • TRUNCATE
      • UNLISTEN
      • UPDATE
      • VACUUM
      • VALUES
    • II. PostgreSQL 用戶端工具
      • createdb
      • createuser
      • dropdb
      • dropuser
      • pgbench
      • pg_dump
      • psql
      • vacuumdb
    • III. PostgreSQL 伺服器應用程式
      • pg_test_timing
      • postgres
  • VII. 資料庫進階
    • 52. 系統目錄
      • 52.3. pg_am
      • 52.7. pg_attribute
      • 52.8. pg_authid
      • 52.9. pg_auth_members
      • 52.11 pg_class
      • 52.12. pg_collation
      • 52.13. pg_constraint
      • 52.15 pg_database
      • 52.26 pg_index
      • 52.29. pg_language
      • 52.32. pg_namespace
      • 52.33. pg_opclass
      • 52.38. pg_policy
      • 52.39. pg_proc
      • 52.44. pg_rewrite
      • 52.50. pg_statistic
      • 52.51. pg_statistic_ext
      • 52.54. pg_tablespace
      • 52.56. pg_trigger
      • 52.62. pg_type
      • 52.79. pg_replication_origin_status
      • 52.81 pg_roles
      • 52.85. pg_settings
      • 52.87. pg_stats
    • 53. Frontend/Backend Protocol
      • 53.1. Overview
      • 53.2. Message Flow
      • 53.3. SASL Authentication
      • 53.4. Streaming Replication Protocol
      • 53.5. Logical Streaming Replication Protocol
      • 53.6. Message Data Types
      • 53.7. Message Formats
      • 53.8. Error and Notice Message Fields
      • 53.9. Logical Replication Message Formats
      • 53.10. Summary of Changes since Protocol 2.0
    • 54. PostgreSQL 程式撰寫慣例
      • 54.1. Formatting
      • 54.2. Reporting Errors Within the Server
      • 54.3. Error Message Style Guide
      • 54.4. Miscellaneous Coding Conventions
    • 56. Writing A Procedural Language Handler
    • 64. GiST Indexes
      • 64.1. Introduction
      • 64.2. Built-in Operator Classes
      • 64.3. Extensibility
      • 64.4. Implementation
      • 64.5. Examples
    • 65. SP-GiST Indexes
      • 65.1. Introduction
      • 65.2. Built-in Operator Classes
      • 65.3. Extensibility
      • 65.4. Implementation
      • 65.5. Examples
    • 66. GIN 索引
      • 66.1. 簡介
      • 66.2. 內建運算子類
      • 66.3. Extensibility
      • 66.4. Implementation
      • 66.5. GIN Tips and Tricks
      • 66.6. Limitations
      • 66.7. Examples
    • 67. BRIN Indexes
      • 67.1. Introduction
      • 67.2. Built-in Operator Classes
      • 67.3. Extensibility
    • 68. 資料庫實體儲存格式
      • 68.2. TOAST
      • 68.4 可視性映射表(Visibility Map)
    • 70. How the Planner Uses Statistics
      • 70.2. Multivariate Statistics Examples
  • VIII. 附錄
    • A. PostgreSQL錯誤代碼
    • B. 日期時間格式支援
      • B.1. 日期時間解譯流程
      • B.2. 日期時間慣用字
      • B.3. 日期時間設定檔
      • B.4. 日期時間的沿革
    • C. SQL 關鍵字
    • D. SQL 相容性
    • E. 版本資訊
    • F. 延伸支援模組
      • F.4. auto_explain
      • F.11. dblink
        • dblink
      • F.33. pg_visibility
    • G. Additional Supplied Programs
      • G.1. Client Applications
        • oid2name
        • vacuumlo
      • G.2. Server Applications
        • pg_standby
    • H. 外部專案
      • H.1. 用戶端介面
      • H.2. Administration Tools
      • H.3. Procedural Languages
      • H.4. Extensions
    • I. The Source Code Repository
      • I.1. Getting The Source via Git
    • J. 文件取得
    • K. 縮寫字
  • 參考書目
Powered by GitBook
On this page
  • 9.26.1. 組態設定函數
  • 9.26.2. Server Signaling Functions
  • 9.26.3. Backup Control Functions
  • 9.26.4. Recovery Control Functions
  • 9.26.5. Snapshot Synchronization Functions
  • 9.26.6. Replication Functions
  • 9.26.7. Database Object Management Functions
  • 9.26.8. Index Maintenance Functions
  • 9.26.9. Generic File Access Functions
  • 9.26.10. Advisory Lock Functions

Was this helpful?

Edit on Git
Export as PDF
  1. II. SQL查詢語言
  2. 9. 函式及運算子

9.26. 系統管理函式

Previous9.25. 系統資訊函數Next9.27. 觸發函式

Last updated 6 years ago

Was this helpful?

本節中描述的函數用於控制和監控 PostgreSQL 環境。

9.26.1. 組態設定函數

列出了可用於查詢和變更執行時組態參數的函數。

Table 9.77. Configuration Settings Functions

函數名稱

回傳型別

說明

current_setting(setting_name [, missing_ok ])

text

取得目前設定值

set_config(setting_name, new_value, is_local)

text

設定參數並回傳新值

函數 current_setting 會產生設定 setting_name 目前的值。它對應於 SQL 指令 SHOW。範例如下:

SELECT current_setting('datestyle');

 current_setting
-----------------
 ISO, MDY
(1 row)

如果沒有名為 setting_name 的設定,則 current_setting 會拋出錯誤,除非有設定了 missing_ok,並且為 true。

set_config 將參數 setting_name 設定為 new_value。如果 is_local 為true,則新值僅適用於目前的交易事務。如果要將新值套用於目前連線之中,請改用 false。此函數對應於 SQL 命令 SET。範例如下:

SELECT set_config('log_statement_stats', 'off', false);

 set_config
------------
 off
(1 row)

9.26.2. Server Signaling Functions

Table 9.78. Server Signaling Functions

Name

Return Type

Description

pg_cancel_backend(pidint)

boolean

Cancel a backend's current query. This is also allowed if the calling role is a member of the role whose backend is being canceled or the calling role has been granted pg_signal_backend, however only superusers can cancel superuser backends.

pg_reload_conf()

boolean

Cause server processes to reload their configuration files

pg_rotate_logfile()

boolean

Rotate server's log file

pg_terminate_backend(pidint)

boolean

Terminate a backend. This is also allowed if the calling role is a member of the role whose backend is being terminated or the calling role has been grantedpg_signal_backend, however only superusers can terminate superuser backends.

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.

9.26.3. Backup Control Functions

Table 9.79. Backup Control Functions

Name

Return Type

Description

pg_create_restore_point(name text)

pg_lsn

Create a named point for performing restore (restricted to superusers by default, but other users can be granted EXECUTE to run the function)

pg_current_wal_flush_lsn()

pg_lsn

Get current write-ahead log flush location

pg_current_wal_insert_lsn()

pg_lsn

Get current write-ahead log insert location

pg_current_wal_lsn()

pg_lsn

Get current write-ahead log write location

pg_start_backup(label text [, fast boolean [,exclusive boolean ]])

pg_lsn

Prepare for performing on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)

pg_stop_backup()

pg_lsn

Finish performing exclusive on-line backup (restricted to superusers by default, but other users can be granted EXECUTE to run the function)

pg_stop_backup(exclusive boolean [,wait_for_archive boolean ])

setof record

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)

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_wal()

pg_lsn

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)

pg_walfile_name(lsn pg_lsn)

text

Convert write-ahead log location to file name

pg_walfile_name_offset(lsn pg_lsn)

text, integer

Convert write-ahead log location to file name and decimal byte offset within file

pg_wal_lsn_diff(lsn pg_lsn, lsn pg_lsn)

numeric

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.

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.

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_labeland 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_walon 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_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:

postgres=# SELECT * FROM pg_walfile_name_offset(pg_stop_backup());
        file_name         | file_offset 
--------------------------+-------------
 00000001000000000000000D |     4039624
(1 row)

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.

9.26.4. Recovery Control Functions

Table 9.80. Recovery Information Functions

Name

Return Type

Description

pg_is_in_recovery()

bool

True if recovery is still in progress.

pg_last_wal_receive_lsn()

pg_lsn

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.

pg_last_wal_replay_lsn()

pg_lsn

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.

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.

Table 9.81. Recovery Control Functions

Name

Return Type

Description

pg_is_wal_replay_paused()

bool

True if recovery is paused.

pg_wal_replay_pause()

void

Pauses recovery immediately (restricted to superusers by default, but other users can be granted EXECUTE to run the function).

pg_wal_replay_resume()

void

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.

Table 9.82. Snapshot Synchronization Functions

Name

Return Type

Description

pg_export_snapshot()

text

Save the current snapshot and return its identifier

9.26.6. Replication Functions

Table 9.83. Replication SQL Functions

Function

Return Type

Description

pg_create_physical_replication_slot(slot_namename [, immediately_reserve boolean,temporary boolean])

(slot_namename, lsnpg_lsn)

pg_drop_replication_slot(slot_name name)

void

Drops the physical or logical replication slot named slot_name. Same as replication protocol command DROP_REPLICATION_SLOT. For logical slots, this must be called when connected to the same database the slot was created on.

pg_create_logical_replication_slot(slot_namename, plugin name [, temporary boolean])

(slot_namename, lsnpg_lsn)

Creates a new logical (decoding) replication slot named slot_name using the output plugin plugin. The optional third parameter, temporary, when set to true, specifies that the slot should not be permanently stored to disk and is only meant for use by current session. Temporary slots are also released upon any error. A call to this function has the same effect as the replication protocol command CREATE_REPLICATION_SLOT ... LOGICAL.

pg_logical_slot_get_changes(slot_name name,upto_lsn pg_lsn, upto_nchanges int, VARIADICoptions text[])

(lsnpg_lsn, xid xid, data text)

Returns changes in the slot slot_name, starting from the point at which since changes have been consumed last. If upto_lsnand upto_nchanges are NULL, logical decoding will continue until end of WAL. If upto_lsn is non-NULL, decoding will include only those transactions which commit prior to the specified LSN. If upto_nchanges is non-NULL, decoding will stop when the number of rows produced by decoding exceeds the specified value. Note, however, that the actual number of rows returned may be larger, since this limit is only checked after adding the rows produced when decoding each new transaction commit.

pg_logical_slot_peek_changes(slot_name name,upto_lsn pg_lsn, upto_nchanges int, VARIADICoptions text[])

(lsnpg_lsn, xid xid, data text)

Behaves just like the pg_logical_slot_get_changes() function, except that changes are not consumed; that is, they will be returned again on future calls.

pg_logical_slot_get_binary_changes(slot_namename, upto_lsn pg_lsn, upto_nchanges int, VARIADIC options text[])

(lsnpg_lsn, xid xid, databytea)

Behaves just like the pg_logical_slot_get_changes() function, except that changes are returned as bytea.

pg_logical_slot_peek_binary_changes(slot_namename, upto_lsn pg_lsn, upto_nchanges int, VARIADIC options text[])

(lsnpg_lsn, xid xid, databytea)

Behaves just like the pg_logical_slot_get_changes() function, except that changes are returned as bytea and that changes are not consumed; that is, they will be returned again on future calls.

pg_replication_slot_advance(slot_name name,upto_lsn pg_lsn)

(slot_namename, end_lsnpg_lsn) bool

Advances the current confirmed position of a replication slot named slot_name. The slot will not be moved backwards, and it will not be moved beyond the current insert location. Returns name of the slot and real position to which it was advanced to.

pg_replication_origin_create(node_name text)

oid

Create a replication origin with the given external name, and return the internal id assigned to it.

pg_replication_origin_drop(node_name text)

void

Delete a previously created replication origin, including any associated replay progress.

pg_replication_origin_oid(node_name text)

oid

Lookup a replication origin by name and return the internal id. If no corresponding replication origin is found an error is thrown.

pg_replication_origin_session_setup(node_nametext)

void

Mark the current session as replaying from the given origin, allowing replay progress to be tracked. Use pg_replication_origin_session_reset to revert. Can only be used if no previous origin is configured.

pg_replication_origin_session_reset()

void

Cancel the effects of pg_replication_origin_session_setup().

pg_replication_origin_session_is_setup()

bool

Has a replication origin been configured in the current session?

pg_replication_origin_session_progress(flushbool)

pg_lsn

Return the replay location for the replication origin configured in the current session. The parameter flush determines whether the corresponding local transaction will be guaranteed to have been flushed to disk or not.

pg_replication_origin_xact_setup(origin_lsnpg_lsn, origin_timestamp timestamptz)

void

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 pg_replication_origin_session_setup().

pg_replication_origin_xact_reset()

void

Cancel the effects of pg_replication_origin_xact_setup().

pg_replication_origin_advance(node_name text,lsn pg_lsn)

void

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.

pg_replication_origin_progress(node_nametext, flush bool)

pg_lsn

Return the replay location for the given replication origin. The parameter flush determines whether the corresponding local transaction will be guaranteed to have been flushed to disk or not.

pg_logical_emit_message(transactional bool,prefix text, content text)

pg_lsn

Emit text logical decoding message. This can be used to pass generic messages to logical decoding plugins through WAL. The parameter transactional specifies if the message should be part of current transaction or if it should be written immediately and decoded as soon as the logical decoding reads the record. The prefix is textual prefix used by the logical decoding plugins to easily recognize interesting messages for them. The content is the text of the message.

pg_logical_emit_message(transactional bool,prefix text, content bytea)

pg_lsn

Emit binary logical decoding message. This can be used to pass generic messages to logical decoding plugins through WAL. The parameter transactional specifies if the message should be part of current transaction or if it should be written immediately and decoded as soon as the logical decoding reads the record. The prefix is textual prefix used by the logical decoding plugins to easily recognize interesting messages for them. The content is the binary content of the message.

9.26.7. Database Object Management Functions

Table 9.84. 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_bytes(text)

bigint

Converts a size in human-readable format with size units into bytes

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 CONNECTpermission on the specified database (which is granted by default), or be a member of the pg_read_all_stats role. To use pg_tablespace_size, you must have CREATE permission on the specified tablespace, or be a member of the pg_read_all_stats role 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.

  • '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.

Table 9.85. 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_filenode_relation(tablespace oid, filenode oid)

regclass

Find the relation associated with a given tablespace and filenode

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.86. Collation Management Functions

Name

Return Type

Description

pg_collation_actual_version(oid)

text

Return actual version of collation from operating system

pg_import_system_collations(schema regnamespace)

integer

Import operating system collations

9.26.8. Index Maintenance Functions

Table 9.87. Index Maintenance Functions

Name

Return Type

Description

brin_summarize_new_values(index regclass)

integer

summarize page ranges not already summarized

brin_summarize_range(index regclass, blockNumber bigint)

integer

summarize the page range covering the given block, if not already summarized

brin_desummarize_range(index regclass, blockNumber bigint)

integer

de-summarize the page range covering the given block, if summarized

gin_clean_pending_list(index regclass)

bigint

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.

9.26.9. Generic File Access Functions

Note that granting users the EXECUTE privilege on the 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.88. Generic File Access Functions

Name

Return Type

Description

pg_ls_dir(dirname text [, missing_ok boolean,include_dot_dirs boolean])

setof text

List the contents of a directory. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_ls_logdir()

setof record

List the name, size, and last modification time of files in the log directory. Access is granted to members of the pg_monitor role and may be granted to other non-superuser roles.

pg_ls_waldir()

setof record

List the name, size, and last modification time of files in the WAL directory. Access is granted to members of the pg_monitor role and may be granted to other non-superuser roles.

pg_read_file(filename text [, offset bigint, lengthbigint [, missing_ok boolean] ])

text

Return the contents of a text file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_read_binary_file(filename text [, offset bigint,length bigint [, missing_ok boolean] ])

bytea

Return the contents of a file. Restricted to superusers by default, but other users can be granted EXECUTE to run the function.

pg_stat_file(filename text[, missing_ok boolean])

record

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_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;

9.26.10. Advisory Lock Functions

Table 9.89. 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 falseif 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.

The functions shown in 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.

The functions shown in assist in making on-line backups. These functions cannot be executed during recovery (except pg_is_in_backup, pg_backup_start_time and pg_wal_lsn_diff).

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 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_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 to get the replication lag.

For details about proper usage of these functions, see .

The functions shown in provide information about the current status of the standby. These functions may be executed both during recovery and in normal running.

The functions shown in control the progress of recovery. These functions may be executed only during recovery.

Snapshots are exported with the pg_export_snapshot function, shown in , and imported with the command.

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 .

See for details of how to use an exported snapshot.

The functions shown in are for controlling and interacting with replication features. See , , and for information about the underlying features. Use of these functions is restricted to superusers.

Many of these functions have equivalent commands in the replication protocol; see .

The functions described in , , and are also relevant for replication.

Creates a new physical replication slot named slot_name. The optional second parameter, when true, specifies that the LSNfor this replication slot be reserved immediately; otherwise the LSN is reserved on first connection from a streaming replication client. Streaming changes from a physical slot is only possible with the streaming-replication protocol — see . The optional third parameter, temporary, when set to true, specifies that the slot should not be permanently stored to disk and is only meant for use by current session. Temporary slots are also released upon any error. This function corresponds to the replication protocol command CREATE_REPLICATION_SLOT ... PHYSICAL.

The functions shown in calculate the disk space usage of database objects.

'fsm' returns the size of the Free Space Map (see ) associated with the relation.

'vm' returns the size of the Visibility Map (see ) associated with the relation.

The functions shown in assist in identifying the specific disk files associated with database objects.

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 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.

lists functions used to manage 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 .

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 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.

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.

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 and for details of the pending list and fastupdate option.

The functions shown in 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.

The functions shown in manage advisory locks. For details about proper use of these functions, see .

Table 9.78
Table 9.79
recovery_target_name
Table 9.79
Section 25.3
Table 9.80
Table 9.81
Table 9.82
SET TRANSACTION
PREPARE TRANSACTION
SET TRANSACTION
Table 9.83
Section 26.2.5
Section 26.2.6
Chapter 50
Section 53.4
Section 9.26.3
Section 9.26.4
Section 9.26.5
Table 9.84
Section 68.3
Section 68.4
Table 9.85
Section 68.1
Table 9.86
ALTER COLLATION
Section 23.2.2
Table 9.87
Section 66.4.1
Section 66.5
Table 9.88
Table 9.89
Section 13.3.5
Table 9.77
Section 53.4